{% 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