with int_monthly_aggregated_metrics_history_by_deal as ( select * from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }} ), int_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}), deal_attributes as ( select id_deal, coalesce( main_billing_country_iso_3_per_deal, 'UNSET' ) as main_billing_country_iso_3_per_deal, effective_deal_start_month, hubspot_deal_cancellation_month, coalesce( hubspot_listing_segmentation, 'UNSET' ) as hubspot_listing_segmentation from int_kpis__dimension_deals -- Exclude deals without live dates where effective_deal_start_date_utc is not null ) -- Calculate expected MRR per deal by each dimension select (date_trunc('month', m.date) + interval '2 month' - interval '1 day')::date as date, 'by_number_of_listings' as dimension, d.hubspot_listing_segmentation as dimension_value, sum(coalesce(m.total_revenue_in_gbp, 0)) / count(*) as expected_mrr_per_deal from 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) >= date_trunc('month', d.effective_deal_start_month) and date_trunc('month', m.date) <= coalesce(d.hubspot_deal_cancellation_month, '2099-01-01') and date_trunc('month', m.date)::date <> date_trunc('month', now())::date where d.hubspot_listing_segmentation <> 'UNSET' group by 1, 2, 3 union all select (date_trunc('month', m.date) + interval '2 month' - interval '1 day')::date as date, 'by_billing_country' as dimension, d.main_billing_country_iso_3_per_deal as dimension_value, sum(coalesce(m.total_revenue_in_gbp, 0)) / count(*) as expected_mrr_per_deal from 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) >= date_trunc('month', d.effective_deal_start_month) and date_trunc('month', m.date) <= coalesce(d.hubspot_deal_cancellation_month, '2099-01-01') and date_trunc('month', m.date)::date <> date_trunc('month', now())::date where d.hubspot_listing_segmentation <> 'UNSET' group by 1, 2, 3 union all select (date_trunc('month', m.date) + interval '2 month' - interval '1 day')::date as date, 'global' as dimension, 'global' as dimension_value, sum(coalesce(m.total_revenue_in_gbp, 0)) / count(*) as expected_mrr_per_deal from 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) >= date_trunc('month', d.effective_deal_start_month) and date_trunc('month', m.date) <= coalesce(d.hubspot_deal_cancellation_month, '2099-01-01') and date_trunc('month', m.date)::date <> date_trunc('month', now())::date where d.hubspot_listing_segmentation <> 'UNSET' group by 1, 2, 3