creates onboarding mrr model

This commit is contained in:
Joaquin Ossa 2025-01-14 11:48:44 +01:00
parent 77a70d21a4
commit 1db8a050ce
2 changed files with 49 additions and 26 deletions

View file

@ -1,10 +1,12 @@
with with
deal_attributes as ( deal_attributes as (
select select
id_deal, ihd.id_deal,
date_trunc('month', live_date_utc)::date as live_month, date_trunc('month', live_date_utc)::date as live_month,
date_trunc('month', cancellation_date_utc)::date as cancellation_month, date_trunc('month', cancellation_date_utc)::date as cancellation_month,
amount_of_properties, coalesce(
icd.main_billing_country_iso_3_per_deal, 'UNSET'
) as main_billing_country_iso_3_per_deal,
case case
when amount_of_properties between 1 and 5 when amount_of_properties between 1 and 5
then '01|05' then '01|05'
@ -17,12 +19,16 @@ with
else 'UNSET' else 'UNSET'
end as property_bucket end as property_bucket
from {{ ref("int_hubspot__deal") }} ihd from {{ ref("int_hubspot__deal") }} ihd
left join {{ ref("int_core__deal") }} icd on ihd.id_deal = icd.id_deal
-- Exclude deals without live dates -- Exclude deals without live dates
where live_date_utc is not null where live_date_utc is not null
), ),
monthly_revenue_per_property_bucket as ( monthly_revenue_per_property_bucket as (
select select
date_trunc('month', m.date)::date as metric_month, date_trunc('month', m.date)::date as metric_month,
coalesce(
d.main_billing_country_iso_3_per_deal, 'global'
) as main_billing_country_iso_3,
coalesce(d.property_bucket, 'global') as property_bucket, coalesce(d.property_bucket, 'global') as property_bucket,
count(*) as deals_active_in_month, count(*) as deals_active_in_month,
sum(coalesce(m.total_revenue_in_gbp, 0)) as total_revenue_in_gbp sum(coalesce(m.total_revenue_in_gbp, 0)) as total_revenue_in_gbp
@ -35,25 +41,27 @@ with
<= coalesce(d.cancellation_month, '2099-01-01') <= coalesce(d.cancellation_month, '2099-01-01')
and date_trunc('month', m.date)::date <> date_trunc('month', now())::date and date_trunc('month', m.date)::date <> date_trunc('month', now())::date
where d.property_bucket <> 'UNSET' where d.property_bucket <> 'UNSET'
group by rollup (date_trunc('month', m.date)::date, d.property_bucket) group by
rollup (
date_trunc('month', m.date)::date,
d.property_bucket,
d.main_billing_country_iso_3_per_deal
)
having date_trunc('month', m.date)::date is not null having date_trunc('month', m.date)::date is not null
) )
select select
r.metric_month, (r.metric_month - interval '1 day')::date as date,
case r.main_billing_country_iso_3 as billing_country,
when r.metric_month + interval '12 months' >= date_trunc('month', now())::date r.property_bucket as number_of_listings,
then false sum(coalesce(m.total_revenue_in_gbp, 0)) as total_revenue_in_gbp,
else true
end as is_full_12_months_period,
r.property_bucket,
sum(coalesce(m.total_revenue_in_gbp, 0)) as cumulative_total_revenue_in_gbp,
sum(m.deals_active_in_month) as total_active_months, sum(m.deals_active_in_month) as total_active_months,
sum(coalesce(m.total_revenue_in_gbp, 0)) sum(coalesce(m.total_revenue_in_gbp, 0))
/ sum(m.deals_active_in_month) as expected_mrr_per_month / sum(m.deals_active_in_month) as expected_mrr
from monthly_revenue_per_property_bucket m from monthly_revenue_per_property_bucket m
inner join inner join
monthly_revenue_per_property_bucket r monthly_revenue_per_property_bucket r
on r.metric_month > m.metric_month on r.metric_month > m.metric_month
and r.metric_month <= m.metric_month + interval '12 months' and r.metric_month <= m.metric_month + interval '12 months'
and r.property_bucket = m.property_bucket and r.property_bucket = m.property_bucket
group by r.metric_month, is_full_12_months_period, r.property_bucket and r.main_billing_country_iso_3 = m.main_billing_country_iso_3
group by r.metric_month, r.property_bucket, r.main_billing_country_iso_3

View file

@ -1707,10 +1707,9 @@ models:
data_type: boolean data_type: boolean
description: "Flag to indicate if the deal is in Xero." description: "Flag to indicate if the deal is in Xero."
- name: int_onboarding_mrr_by_segment - name: int_deals_onboarding_mrr
description: | description: |
"This table provides data on the Onboarding Monthly Recurring Revenue (MRR), "This table provides data on the Onboarding Monthly Recurring Revenue (MRR).
segmented by the number of properties specified in each deal on HubSpot.
The Onboarding MRR is an estimate of the expected monthly revenue generated by The Onboarding MRR is an estimate of the expected monthly revenue generated by
each new deal. It is calculated by taking the total revenue generated by all each new deal. It is calculated by taking the total revenue generated by all
active accounts over the last 12 months and dividing it by the number of active active accounts over the last 12 months and dividing it by the number of active
@ -1719,19 +1718,26 @@ models:
- name: date - name: date
data_type: date data_type: date
description: | description: |
"Date from which the data is being taken. It is the first day of the month." "Last date of the month for which the data is reported.
It considers the data from the previous 12 months up to the date."
data_tests:
- not_null
- is_last_day_of_month
- name: is_full_12_months_period - name: billing_country
data_type: boolean data_type: text
description: | description: |
"Boolean that indicates if there is a full 12 months period of data." "ISO 3166-1 alpha-3 main country code in which the Deals are billed"
data_tests:
- not_null
- name: property_bucket - name: number_of_listings
data_type: text data_type: text
description: | description: |
"Segmentation based on the number of properties specified by each deal "Segmentation based on the number of properties specified by each deal
in HubSpot." in HubSpot."
data_tests: data_tests:
- not_null
- accepted_values: - accepted_values:
values: values:
- "01|05" - "01|05"
@ -1740,17 +1746,26 @@ models:
- "61+" - "61+"
- "global" - "global"
- name: cumulative_total_revenue_in_gbp - name: total_revenue_in_gbp
data_type: numeric data_type: numeric
description: | description: |
"Total revenue revenue "Total revenue accumulated by all active accounts over the last 12 months."
data_tests:
- not_null
- name: total_active_months - name: total_active_months
data_type: numeric data_type: numeric
description: | description: |
"D "Total number of active months for all accounts over the last 12 months."
data_tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: expected_mrr_per_month - name: expected_mrr
data_type: numeric data_type: numeric
description: | description: |
"D "Expected MRR for each new deal."
data_tests:
- not_null