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

67 lines
2.9 KiB
SQL

with
deal_attributes as (
select
ihd.id_deal,
date_trunc('month', live_date_utc)::date as live_month,
date_trunc('month', cancellation_date_utc)::date as cancellation_month,
coalesce(
icd.main_billing_country_iso_3_per_deal, 'UNSET'
) as main_billing_country_iso_3_per_deal,
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
left join {{ ref("int_core__deal") }} icd on ihd.id_deal = icd.id_deal
-- Exclude deals without live dates
where live_date_utc is not null
),
monthly_revenue_per_property_bucket as (
select
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,
count(*) 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')
and date_trunc('month', m.date)::date <> date_trunc('month', now())::date
where d.property_bucket <> 'UNSET'
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
)
select
(r.metric_month - interval '1 day')::date as date,
r.main_billing_country_iso_3 as billing_country,
r.property_bucket as number_of_listings,
sum(coalesce(m.total_revenue_in_gbp, 0)) as 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
from monthly_revenue_per_property_bucket m
inner join
monthly_revenue_per_property_bucket 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
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