# Description Simplifies the code for the models: * int_monthly_12m_window_contribution_by_deal * int_monthly_churn_metrics By just removing the additive contribution approach. This also reduces the schema file information of these 2 models. I also adapted the description to clarify the state of the models. No rush to merge this. # Checklist - [X] The edited models and dependants run properly with production data. - [X] The edited models are sufficiently documented. - [X] The edited models contain PK tests, and I've ran and passed them. - [X] I have checked for DRY opportunities with other models and docs. - [X] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #22691
89 lines
3.5 KiB
SQL
89 lines
3.5 KiB
SQL
{% set dimensions = get_kpi_dimensions() %}
|
|
{% set churn_lifecycle_states = "('05-Churning')" %}
|
|
|
|
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
|
with
|
|
int_monthly_12m_window_contribution_by_deal as (
|
|
select * from {{ ref("int_monthly_12m_window_contribution_by_deal") }}
|
|
),
|
|
int_dates_mtd_by_dimension as (
|
|
select * from {{ ref("int_dates_mtd_by_dimension") }}
|
|
),
|
|
int_core__mtd_accommodation_segmentation as (
|
|
select * from {{ ref("int_core__mtd_accommodation_segmentation") }}
|
|
),
|
|
int_core__deal as (select * from {{ ref("int_core__deal") }}),
|
|
churn_metrics_per_date as (
|
|
{% for dimension in dimensions %}
|
|
select
|
|
m12wc.date,
|
|
{{ dimension.dimension }} as dimension,
|
|
{{ dimension.dimension_value }} as dimension_value,
|
|
sum(
|
|
case
|
|
when m12wc.deal_lifecycle_state in {{ churn_lifecycle_states }}
|
|
then m12wc.total_revenue_12m_average_contribution
|
|
else 0
|
|
end
|
|
) as total_revenue_churn_average_contribution,
|
|
sum(
|
|
case
|
|
when m12wc.deal_lifecycle_state in {{ churn_lifecycle_states }}
|
|
then m12wc.created_bookings_12m_average_contribution
|
|
else 0
|
|
end
|
|
) as created_bookings_churn_average_contribution,
|
|
sum(
|
|
case
|
|
when m12wc.deal_lifecycle_state in {{ churn_lifecycle_states }}
|
|
then m12wc.listings_booked_in_month_12m_average_contribution
|
|
else 0
|
|
end
|
|
) as listings_booked_in_month_churn_average_contribution
|
|
from int_monthly_12m_window_contribution_by_deal m12wc
|
|
{% if dimension.dimension == "'by_number_of_listings'" %}
|
|
inner join
|
|
int_core__mtd_accommodation_segmentation mas
|
|
on m12wc.id_deal = mas.id_deal
|
|
and m12wc.date = mas.date
|
|
{% elif dimension.dimension == "'by_billing_country'" %}
|
|
inner join
|
|
int_core__deal ud
|
|
on m12wc.id_deal = ud.id_deal
|
|
and ud.main_billing_country_iso_3_per_deal is not null
|
|
{% endif %}
|
|
where deal_lifecycle_state is not null
|
|
group by 1, 2, 3
|
|
{% if not loop.last %}
|
|
union all
|
|
{% endif %}
|
|
{% endfor %}
|
|
)
|
|
-- Final aggregation of subqueries --
|
|
select
|
|
d.year,
|
|
d.month,
|
|
d.day,
|
|
d.date,
|
|
d.dimension,
|
|
d.dimension_value,
|
|
d.is_end_of_month,
|
|
d.is_current_month,
|
|
cast(
|
|
c.total_revenue_churn_average_contribution as numeric(19, 6)
|
|
) as total_revenue_churn_average_contribution,
|
|
cast(
|
|
c.created_bookings_churn_average_contribution as numeric(19, 6)
|
|
) as created_bookings_churn_average_contribution,
|
|
cast(
|
|
c.listings_booked_in_month_churn_average_contribution as numeric(19, 6)
|
|
) as listings_booked_in_month_churn_average_contribution
|
|
from int_dates_mtd_by_dimension d
|
|
left join
|
|
churn_metrics_per_date c
|
|
on c.date = d.date
|
|
and c.dimension = d.dimension
|
|
and c.dimension_value = d.dimension_value
|
|
-- Remove current month dates since data won't be available anyway. This is specific
|
|
-- for this churn metrics model
|
|
where d.is_current_month = 0
|