created new model to get all mrr metrics

This commit is contained in:
Joaquin Ossa 2025-01-28 12:26:53 +01:00
parent 39de8617b7
commit 8bd5851235
3 changed files with 82 additions and 61 deletions

View file

@ -0,0 +1,70 @@
with
monthly_new_deals as (
select
date_trunc('MONTH', effective_deal_start_date_utc)::date as start_month,
hubspot_listing_segmentation,
count(id_deal) as number_of_new_deals
from {{ ref("int_kpis__dimension_deals") }}
group by 1, 2
),
onboarding_mrr_metrics as (
select
mom.date,
'by_number_of_listings' as dimension,
mom.hubspot_listing_segmentation as dimension_value,
mnd.number_of_new_deals,
mom.expected_mrr as expected_mrr_per_deal,
mom.expected_mrr * mnd.number_of_new_deals as expected_mrr
from {{ ref("int_monthly_onboarding_mrr_metrics") }} mom
left join
monthly_new_deals mnd
on date_trunc('MONTH', mom.date)::date = mnd.start_month
and mom.hubspot_listing_segmentation = mnd.hubspot_listing_segmentation
where
mom.main_billing_country_iso_3 = 'global'
and mom.hubspot_listing_segmentation <> 'global'
union all
select
date,
'by_billing_country' as dimension,
main_billing_country_iso_3 as dimension_value,
null as number_of_new_deals,
expected_mrr as expected_mrr_per_deal,
null as expected_mrr
from {{ ref("int_monthly_onboarding_mrr_metrics") }}
where
hubspot_listing_segmentation = 'global'
and main_billing_country_iso_3 <> 'global'
union all
select
date,
'global' as dimension,
'global' as dimension_value,
null as number_of_new_deals,
expected_mrr as expected_mrr_per_deal,
null as expected_mrr
from {{ ref("int_monthly_onboarding_mrr_metrics") }}
where
hubspot_listing_segmentation = 'global'
and main_billing_country_iso_3 = 'global'
),
global_expected_mrr as (
select
omm.date,
'global' as dimension,
sum(omm.number_of_new_deals) as number_of_new_deals,
sum(omm.number_of_new_deals * omm.expected_mrr_per_deal) as expected_mrr
from onboarding_mrr_metrics omm
where omm.dimension = 'by_number_of_listings'
group by 1, 2
)
select
omm.date,
omm.dimension,
omm.dimension_value,
coalesce(gem.number_of_new_deals, omm.number_of_new_deals) as number_of_new_deals,
omm.expected_mrr_per_deal,
coalesce(gem.expected_mrr, omm.expected_mrr) as expected_mrr
from onboarding_mrr_metrics omm
left join
global_expected_mrr gem on omm.date = gem.date and omm.dimension = gem.dimension

View file

@ -307,10 +307,10 @@
},
{
"order_by": 203,
"metric": "Expected Onboarding MRR per New Account",
"value": "expected_mrr_per_account",
"previous_year_value": "previous_year_expected_mrr_per_account",
"relative_increment": "relative_increment_expected_mrr_per_account",
"metric": "Expected Onboarding MRR per New Deal",
"value": "expected_mrr_per_deal",
"previous_year_value": "previous_year_expected_mrr_per_deal",
"relative_increment": "relative_increment_expected_mrr_per_deal",
"number_format": "currency_gbp",
"increment_sign_format": "positive",
},

View file

@ -171,32 +171,8 @@ with
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
and dimension_value <> 'UNSET'
),
int_monthly_onboarding_mrr_metrics as (
select
date,
'by_number_of_listings' as dimension,
hubspot_listing_segmentation as dimension_value,
expected_mrr
from {{ ref("int_monthly_onboarding_mrr_metrics") }}
where
main_billing_country_iso_3 = 'global'
and hubspot_listing_segmentation <> 'global'
union all
select
date,
'by_billing_country' as dimension,
main_billing_country_iso_3 as dimension_value,
expected_mrr
from {{ ref("int_monthly_onboarding_mrr_metrics") }}
where
hubspot_listing_segmentation = 'global'
and main_billing_country_iso_3 <> 'global'
union all
select date, 'global' as dimension, 'global' as dimension_value, expected_mrr
from {{ ref("int_monthly_onboarding_mrr_metrics") }}
where
hubspot_listing_segmentation = 'global'
and main_billing_country_iso_3 = 'global'
int_mtd_agg_onboarding_mrr_metrics as (
select * from {{ ref("int_mtd_agg_onboarding_mrr_metrics") }}
),
plain_kpi_combination as (
@ -418,11 +394,8 @@ with
}} as revenue_retained_post_resolutions_ratio,
-- ONBOARDING MRR METRIC --
onboarding_mrr.expected_mrr as expected_mrr_per_account,
case
when d.dimension = 'by_number_of_listings' then
onboarding_mrr.expected_mrr * deals.new_deals else null
end as number_of_listings_expected_mrr
onboarding_mrr.expected_mrr_per_deal,
onboarding_mrr.expected_mrr
from int_kpis__agg_dates_main_kpis d
left join
@ -496,32 +469,10 @@ with
and d.dimension = churn.dimension
and d.dimension_value = churn.dimension_value
left join
int_monthly_onboarding_mrr_metrics onboarding_mrr
int_mtd_agg_onboarding_mrr_metrics onboarding_mrr
on d.date = onboarding_mrr.date
and d.dimension = onboarding_mrr.dimension
and d.dimension_value = onboarding_mrr.dimension_value
),
global_expected_mrr as (
select
pkc.year,
pkc.month,
pkc.day,
'global' as dimension,
sum(pkc.new_deals*pkc.expected_mrr_per_account) as global_expected_mrr
from plain_kpi_combination pkc
where
pkc.dimension = 'by_number_of_listings'
group by 1, 2, 3, 4
),
plain_kpi_combination_with_mrr as (
select
pkc.*,
coalesce(gem.global_expected_mrr, pkc.number_of_listings_expected_mrr) as expected_mrr
from plain_kpi_combination pkc
left join global_expected_mrr gem on pkc.year = gem.year
and pkc.month = gem.month
and pkc.day = gem.day
and pkc.dimension = gem.dimension
)
select
@ -663,12 +614,12 @@ select
{{ calculate_safe_relative_increment("revenue_retained_post_resolutions_ratio") }},
-- ONBOARDING MRR METRIC --
{{ calculate_safe_relative_increment("expected_mrr_per_account") }},
{{ calculate_safe_relative_increment("expected_mrr_per_deal") }},
{{ calculate_safe_relative_increment("expected_mrr") }}
from plain_kpi_combination_with_mrr current
from plain_kpi_combination current
left join
plain_kpi_combination_with_mrr previous_year
plain_kpi_combination previous_year
on current.dimension = previous_year.dimension
and current.dimension_value = previous_year.dimension_value
and current.month = previous_year.month