with 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 {{ ref("int_kpis__dimension_deals") }} -- Exclude deals without live dates where effective_deal_start_date_utc is not null ), monthly_revenue_per_number_of_properties as ( select m.date, coalesce( d.main_billing_country_iso_3_per_deal, 'global' ) as main_billing_country_iso_3, coalesce( d.hubspot_listing_segmentation, 'global' ) as hubspot_listing_segmentation, 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) >= 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 cube ( m.date, d.hubspot_listing_segmentation, d.main_billing_country_iso_3_per_deal ) -- Exclude total date aggregation having m.date is not null ) select r.date, r.main_billing_country_iso_3, r.hubspot_listing_segmentation, 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_number_of_properties m inner join monthly_revenue_per_number_of_properties r on r.date >= m.date and r.date < m.date + interval '12 months' and r.hubspot_listing_segmentation = m.hubspot_listing_segmentation and r.main_billing_country_iso_3 = m.main_billing_country_iso_3 where r.main_billing_country_iso_3 <> 'UNSET' group by r.date, r.hubspot_listing_segmentation, r.main_billing_country_iso_3