data-dwh-dbt-project/models/intermediate/cross/int_onboarding_mrr_by_segment.sql
2025-01-14 17:37:58 +01:00

153 lines
6.4 KiB
SQL

with
deal_attributes as (
select
id_deal,
date_trunc('month', live_date_utc)::date as live_month,
date_trunc('month', cancellation_date_utc)::date as cancellation_month,
amount_of_properties,
case
when amount_of_properties between 1 and 5
then '01|05'
when amount_of_properties between 6 and 20
then '06|20'
when amount_of_properties between 21 and 60
then '21|60'
when amount_of_properties >= 61
then '61+'
else 'UNSET'
end as property_bucket
from {{ ref("int_hubspot__deal") }} ihd
where live_date_utc is not null -- exclude deals that do not have live date
),
deal_revenue_attribution_on_live_month as (
select
d.id_deal,
d.live_month,
d.cancellation_month,
d.amount_of_properties,
d.property_bucket,
sum(
case
when
date_trunc('month', m.date)::date
< live_month + interval '12 months'
then coalesce(m.total_revenue_in_gbp, 0)
else 0
end
) as deal_total_revenue_first_12_months_in_gbp,
sum(
case
when
date_trunc('month', m.date)::date
< live_month + interval '12 months'
then 1
else 0
end
) as deal_active_months_first_12_months,
sum(
coalesce(m.total_revenue_in_gbp, 0)
) as deal_total_revenue_all_history_in_gbp,
sum(1) as deal_active_months_all_history
from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }} m
inner join
deal_attributes d
on m.id_deal = d.id_deal
and date_trunc('month', m.date) >= d.live_month
and date_trunc('month', m.date)
<= coalesce(d.cancellation_month, '2099-01-01')
-- Exclude current month due to incomplete Revenue data
and date_trunc('month', m.date)::date <> date_trunc('month', now())::date
group by
d.id_deal,
d.live_month,
d.cancellation_month,
d.amount_of_properties,
d.property_bucket
),
agg_revenue_attribution_on_metric_month as (
select
date_trunc('month', m.date)::date as metric_month,
coalesce(d.property_bucket, 'global') as property_bucket,
count(1) as deals_active_in_month,
sum(coalesce(m.total_revenue_in_gbp, 0)) as total_revenue_in_gbp
from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }} m
inner join
deal_attributes d
on m.id_deal = d.id_deal
and date_trunc('month', m.date) >= d.live_month
and date_trunc('month', m.date)
<= coalesce(d.cancellation_month, '2099-01-01')
-- Exclude current month due to incomplete Revenue data
and date_trunc('month', m.date)::date <> date_trunc('month', now())::date
where d.property_bucket <> 'UNSET'
group by rollup (1, d.property_bucket)
-- Remove global live month after roll-up
having date_trunc('month', m.date)::date is not null
order by 1 desc, 2 desc
),
real_revenue_per_property_bucket_and_live_month as (
select
live_month,
coalesce(property_bucket, 'global') as property_bucket,
count(id_deal) as deals_live_in_month,
sum(
deal_total_revenue_first_12_months_in_gbp
) as total_revenue_first_12_months_in_gbp,
sum(
deal_total_revenue_all_history_in_gbp
) as total_revenue_all_history_in_gbp,
sum(
deal_active_months_first_12_months
) as total_active_months_first_12_months,
sum(deal_active_months_all_history) as total_active_months_all_history,
sum(deal_total_revenue_first_12_months_in_gbp) / sum(
deal_active_months_first_12_months
) as real_weighted_avg_total_revenue_first_12_months,
sum(deal_total_revenue_all_history_in_gbp) / sum(
deal_active_months_all_history
) as real_weighted_avg_total_revenue_all_history
from deal_revenue_attribution_on_live_month
-- In some extreme cases, a Deal can be onboarded but have no backend activity
-- for the next 12 months, and have it later on
-- The following condition removes these deals to avoid computation errors.
where
deal_active_months_first_12_months > 0
-- Remove Unset, those deals that do not have the amount of properties
-- informed
and property_bucket <> 'UNSET'
group by rollup (live_month, property_bucket)
-- Remove global live month after roll-up
having live_month is not null
),
method_two_monthly_revenue_per_bucket_last_12_months as (
select
r.metric_month,
r.property_bucket as 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(coalesce(m.total_revenue_in_gbp, 0))
/ sum(m.deals_active_in_month) as expected_mrr_per_month
from agg_revenue_attribution_on_metric_month m
inner join
agg_revenue_attribution_on_metric_month r
on r.metric_month > m.metric_month
and r.metric_month <= m.metric_month + interval '12 months'
and r.property_bucket = m.property_bucket
group by 1, 2
)
select
case
when r.live_month + interval '12 months' >= date_trunc('month', now())::date
then 1
else 0
end as is_not_full_12_months_period,
r.live_month as metric_month,
r.property_bucket,
r.real_weighted_avg_total_revenue_all_history,
m2.expected_mrr_per_month as m1_expected_mrr_per_month
from real_revenue_per_property_bucket_and_live_month r
left join
method_two_monthly_revenue_per_bucket_last_12_months m2
on r.live_month = m2.metric_month
and r.property_bucket = m2.property_bucket
order by r.live_month desc, r.property_bucket desc