data-dwh-dbt-project/models/intermediate/cross/int_monthly_churn_metrics.sql
Oriol Roqué Paniagua be0b8c41b6 Merged PR 4411: Propagates New Dash/Old Dash/APIs split in KPIs as per Business Scope
# Description

Changes:
* Adapt business_kpis_configuration to include By Business Scope as production dimension.
* Sets in int_mtd_metrics_vs_previous_year the selection of business scope dimension for all KPIs models. This does not affect cross kpis models (churn/mrr). I might need to check later how to adapt Churn to include this dimension, but it's not considered as for this PR. Lastly, Billable Bookings excludes New Dash.
* Adapts condition in int_mtd_metrics_vs_previous_year so MTD values would appear independently of these appearing in the previous year. This is, the model was considering that to show current month MTD values, the dimension needed to exist the year prior. This does not happen with New Dash and I assume we never noticed because in any case, most of our dimensions have quite a long history.
* Adapts int_kpis__agg_dates_main_kpis to include the business scope dimension. By the way it's actually handled, it kind of assumes that a Deal can only be in New or Old Dash (this is correct), but while on New Dash, this deal won't have data for Old Dash (this might not be 100% correct). In any case, the global figure should be ok, and only on the deal + business scope dimensionality this could cause some potential problems. However, this is not being reported anyway at the moment.
* Adapts int_kpis__agg_dates_main_kpis to have a proper variable value for the dimensions, and this is further included in business_kpis_configuration as any other model.

Small changes:
* Adapts Churn metrics to read from dimension_deals rather than core__deals. This should be more accurate anyway.

# Checklist

- [ ] The edited models and dependants run properly with production data.
- [ ] The edited models are sufficiently documented.
- [ ] The edited models contain PK tests, and I've ran and passed them.
- [ ] I have checked for DRY opportunities with other models and docs.
- [ ] I've picked the right materialization for the affected models.

# Other

- [ ] Check if a full-refresh is required after this PR is merged.

Propagates New Dash/Old Dash/APIs split in KPIs as per Business Scope

Related work items: #27356
2025-02-14 14:12:39 +00:00

93 lines
3.7 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,
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,
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