# Description Changes: * Adds Revenue Churn Rate in YTD/MTD Overview. This has several implications, I finally understood how to properly compute a YTD. The problem is that Revenue Churn Rate is a % of the Total "Churned" Revenue in a 12 m period vs. the Total Revenue in the same 12 m period. This is a bit tricky because it's not really additive, because of the Churn definition. Total Churned Revenue is the Revenue that the churned deals in a month generated on that past 12 months prior to churning. So - in order to aggregate it properly, we need to do the sum of the Total Churned Revenue and retrieve the Total Revenue on these 12 months, and THEN compute the Churn rate. This PR mainly retrieves the necessary input from the Churn models and then follows a similar computation as for the rest of YTD/MTD converted metrics. I'll handle Onboarding MRR in a separated PR as this one is quite dense already. # 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: #27609, #27805
111 lines
4.5 KiB
SQL
111 lines
4.5 KiB
SQL
{% set dimensions = get_kpi_dimensions_per_model("CHURN_RATES") %}
|
|
{% 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_kpis__agg_dates_main_kpis as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_dates_main_kpis") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
int_kpis__dimension_daily_accommodation as (
|
|
select * from {{ ref("int_kpis__dimension_daily_accommodation") }}
|
|
),
|
|
int_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}),
|
|
churn_metrics_per_date as (
|
|
{% for dimension in dimensions %}
|
|
select
|
|
m12wc.date,
|
|
{{ dimension.dimension }} as dimension,
|
|
{{ dimension.dimension_value }} as dimension_value,
|
|
|
|
-- Revenue Churn 12m rolling window (absolute figures) --
|
|
sum(
|
|
case
|
|
when m12wc.deal_lifecycle_state in {{ churn_lifecycle_states }}
|
|
then m12wc.avg_total_revenue_preceding_12_months
|
|
else 0
|
|
end
|
|
) as total_revenue_churn_preceding_12_months,
|
|
|
|
-- Global Revenue 12m rolling window --
|
|
max(
|
|
m12wc.avg_global_total_revenue_preceding_12_months
|
|
) as total_revenue_global_preceding_12_months,
|
|
|
|
-- Churn Rates --
|
|
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_kpis__dimension_daily_accommodation dda
|
|
on m12wc.id_deal = dda.id_deal
|
|
and m12wc.date = dda.date
|
|
{% elif dimension.dimension == "'by_billing_country'" %}
|
|
inner join
|
|
int_kpis__dimension_deals 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,
|
|
c.total_revenue_churn_preceding_12_months,
|
|
c.total_revenue_global_preceding_12_months,
|
|
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_kpis__agg_dates_main_kpis 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 = false
|