Merged PR 4935: KPIs Refactor Stage 4 - Onboarding MRR model in KPIs

# Description

Creates a single model in KPIs, aggregated by dimension/dimension value, in a monthly basis; named: `int_kpis__agg_monthly_onboarding_mrr`.

Attention! This substitutes both current models, namely `int_monthly_onboarding_mrr_per_deal` and `int_mtd_agg_onboarding_mrr_revenue`. However, both models are currently used to retrieve data for Main KPIs. I just combined both into one, so it will simplify also the gathering of data later on.

Note that this model is special in the sense that the onboarding mrr per deal is computed for global, listing segmentation and billing country dimensions; while the total onboarding mrr is only done for global and listing segmentation (as it's based on the number of listings segmentation for the total compute).

This has been tested with dbt audit helper and md5. This has been a bit more complex since it's comparing 1 new model vs 2 existing models. For reference, this is the md5 comparison used:

```
SELECT md5(array_agg(md5((t1.*)::varchar))::varchar)
  FROM (
        SELECT
        	mrr.date,
        	mrr.dimension,
        	mrr.dimension_value,
        	mrr.expected_mrr_per_deal,
        	total.number_of_new_deals,
        	total.expected_mrr as total_expected_mrr
          FROM intermediate.int_monthly_onboarding_mrr_per_deal mrr
          left join intermediate.int_mtd_agg_onboarding_mrr_revenue total
          on mrr.date = total.date
          and mrr.dimension = total.dimension
          and mrr.dimension_value = total.dimension_value
         ORDER BY date, dimension, dimension_value
       ) AS t1
union all
SELECT md5(array_agg(md5((t2.*)::varchar))::varchar)
  FROM (
        SELECT *
          FROM intermediate.int_kpis__agg_monthly_onboarding_mrr
         ORDER BY date, dimension, dimension_value
       ) AS t2
```

# 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: #27120, #28949
This commit is contained in:
Oriol Roqué Paniagua 2025-04-07 12:27:28 +00:00
parent 446bd7f7d3
commit dc8eee7128
3 changed files with 195 additions and 1 deletions

View file

@ -134,7 +134,11 @@ Provides a general assignement for the Dimensions available for each KPI
{% set additional_dimensions = [] %}
{# Adds Deal dimension to all models except DEAL metrics #}
{% if entity_name not in ["DEALS", "NEW_DASH_DEALS_OFFERED_SERVICES"] %}
{% if entity_name not in [
"DEALS",
"NEW_DASH_DEALS_OFFERED_SERVICES",
"ONBOARDING_MRR",
] %}
{% set additional_dimensions = additional_dimensions + [dim_deal()] %}
{% endif %}

View file

@ -0,0 +1,114 @@
{% set dimensions = get_kpi_dimensions_per_model("ONBOARDING_MRR") %}
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
with
int_kpis__agg_dates_main_kpis as (
select *
from {{ ref("int_kpis__agg_dates_main_kpis") }}
where
dimension in ('by_deal')
and dimension_value <> 'UNSET'
and is_end_of_month = true
),
total_and_retained_revenue as (
select *
from {{ ref("int_kpis__agg_monthly_total_and_retained_revenue") }}
where dimension in ('by_deal') and dimension_value <> 'UNSET'
),
int_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}),
daily_deals_by_listing_segmentation as (
select date, dimension_value as listing_segmentation, new_deals
from {{ ref("int_kpis__agg_daily_deals") }}
where dimension = 'by_number_of_listings'
),
revenue_per_deal as (
select
admk.date,
-- Shift the date to the end of the next month
(
date_trunc('month', admk.date) + interval '2 month' - interval '1 day'
)::date as next_month_end_date,
admk.dimension_value as id_deal,
-- Use Hubspot Segmentation as listing segmentation. The name of the alias
-- is needed for the macro to work
d.hubspot_listing_segmentation
as active_accommodations_per_deal_segmentation,
coalesce(
d.main_billing_country_iso_3_per_deal, 'UNSET'
) as main_billing_country_iso_3_per_deal,
rev.total_revenue_in_gbp
from int_kpis__agg_dates_main_kpis admk
inner join
int_kpis__dimension_deals d
on admk.dimension_value = d.id_deal
and date_trunc('month', admk.date)
<= coalesce(d.hubspot_deal_cancellation_month, {{ var("end_of_time") }})
left join
total_and_retained_revenue rev
on admk.date = rev.end_date
and admk.dimension_value = rev.dimension_value
where
-- Ensure we are only considering deals with a listing segmentation
-- that have gone live
d.hubspot_listing_segmentation <> 'UNSET'
and d.effective_deal_start_date_utc is not null
),
onboarding_mrr_per_dimension_per_deal as (
-- Calculate onboarding MRR per deal by each dimension
{% for dimension in dimensions %}
select
m.next_month_end_date as date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
sum(coalesce(m.total_revenue_in_gbp, 0))
/ count(m.id_deal) as onboarding_mrr_per_new_deal_in_gbp
from revenue_per_deal m
group by 1, 2, 3
{% if not loop.last %}
union all
{% endif %}
{% endfor %}
),
number_of_listing_onboarding_mrr as (
select
mom.date,
mom.dimension,
mom.dimension_value,
ad.new_deals as new_deals_count,
mom.onboarding_mrr_per_new_deal_in_gbp
* ad.new_deals as total_onboarding_mrr_in_gbp
from onboarding_mrr_per_dimension_per_deal mom
left join
daily_deals_by_listing_segmentation ad
on mom.date = ad.date
and mom.dimension_value = ad.listing_segmentation
where mom.dimension = 'by_number_of_listings'
),
total_onboarding_mrr_per_dimension as (
-- Calculated total onboarding mrr based on the listing segmentation
-- for dimension 'by_number_of_listings' and 'global'. Note that
-- the dimension 'by_billing_country' is not included here.
select
date,
coalesce(dimension, 'global') as dimension,
coalesce(dimension_value, 'global') as dimension_value,
sum(new_deals_count) as new_deals_count,
sum(total_onboarding_mrr_in_gbp) as total_onboarding_mrr_in_gbp
from number_of_listing_onboarding_mrr
group by date, rollup (dimension, dimension_value)
)
select
per_deal.date,
per_deal.dimension,
per_deal.dimension_value,
-- Available for dimensions: 'by_number_of_listings',
-- 'by_billing_country' and 'global'
per_deal.onboarding_mrr_per_new_deal_in_gbp,
-- Available for dimensions: 'by_number_of_listings' and 'global'
total.new_deals_count,
total.total_onboarding_mrr_in_gbp
from onboarding_mrr_per_dimension_per_deal per_deal
left join
total_onboarding_mrr_per_dimension total
on per_deal.date = total.date
and per_deal.dimension = total.dimension
and per_deal.dimension_value = total.dimension_value

View file

@ -8701,3 +8701,79 @@ models:
- name: listings_booked_in_month_churn_average_contribution
data_type: numeric
description: Listings Booked in Month churn rate (average approach).
- name: int_kpis__agg_monthly_onboarding_mrr
description: |
This model contains the monthly aggregated metrics for onboarding MRR.
These metrics refer to the expectation of how much revenue is expected to
be generated from new deals, in average, in a monthly basis. This is a
projected value. Since Revenue is not a timely figure, the onboarding MRR
is shifted by one month. Keep in mind that the number of new deals are
the actual new deals onboarded in the month.
The metrics computed for this model are as follows:
- onboarding_mrr_per_new_deal_in_gbp: How much revenue in a month is expected
to be generated by a new deal?
- total_onboarding_mrr_in_gbp: How much revenue in a month is expected to be
generated by ALL new deals onboarded on that same month?
Additionally, it also contains "new_deals_count" for information purposes.
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- dimension
- dimension_value
columns:
- name: date
data_type: date
description: The date for the monthly metrics, corresponding to the EOM.
data_tests:
- not_null
- name: dimension
data_type: string
description: The dimension or granularity of the metrics.
data_tests:
- accepted_values:
values:
- global
- by_number_of_listings
- by_billing_country
- name: dimension_value
data_type: string
description: The value or segment available for the selected dimension.
data_tests:
- not_null
- name: new_deals_count
data_type: numeric
description: Number of new deals in the month, for information purposes.
- name: onboarding_mrr_per_new_deal_in_gbp
data_type: numeric
description: |
Expected onboarding MRR per new deal in GBP.
This is computed by:
- Gathering all live deals that have a hubspot listing segmentation available.
- Retrieving the total revenue of these deals in a given month.
- Dividing the total revenue by the number of live deals.
This is assumed to be the expected onboarding MRR per each new deal.
data_tests:
- not_null
- name: total_onboarding_mrr_in_gbp
data_type: numeric
description: |
Total expected Onboarding MRR in GBP per date, dimension and dimension value.
This is computed by:
- Gathering the expected onboarding MRR per new deal for the dimension 'by_number_of_listings'
- Gathering the number of new deals for the dimension 'by_number_of_listings'
- Multiplying the two values, to get the total onboarding MRR for each listing segment
- Rolling up the total onboarding MRR for each listing segment to get the total onboarding MRR
for the Global dimension.
This is not available for 'by_billing_country' dimension, thus null values are expected.