diff --git a/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql new file mode 100644 index 0000000..f87589d --- /dev/null +++ b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql @@ -0,0 +1,63 @@ +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 + rollup ( + 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 diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index 6daf234..a19a116 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1706,3 +1706,76 @@ models: - name: is_deal_in_xero data_type: boolean description: "Flag to indicate if the deal is in Xero." + + - name: int_monthly_onboarding_mrr_metrics + description: | + "This table provides data on the Onboarding Monthly Recurring Revenue (MRR). + The Onboarding MRR is an estimate of the expected monthly revenue generated by + each new deal. It is calculated by taking the total revenue generated by all + active accounts over the last 12 months and dividing it by the number of active + months for each account." + + data_tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - main_billing_country_iso_3 + - hubspot_listing_segmentation + + columns: + - name: date + data_type: date + description: | + "Date representing the last day of the month. The metrics are calculated using data + from the 12 months leading up to and including this date. Along with + `main_billing_country_iso_3` and `hubspot_listing_segmentation`, this field serves + as part of the primary key for the model." + data_tests: + - not_null + - is_last_day_of_month + + - name: main_billing_country_iso_3 + data_type: text + description: | + "Main billing country code from ISO 3166" + data_tests: + - not_null + + - name: hubspot_listing_segmentation + data_type: text + description: | + "Segmentation based on the number of properties specified by each deal + in HubSpot." + data_tests: + - not_null + - accepted_values: + values: + - "01-05" + - "06-20" + - "21-60" + - "61+" + - "global" + + - name: total_revenue_in_gbp + data_type: numeric + description: | + "Total revenue accumulated by all active accounts over the last 12 months." + data_tests: + - not_null + + - name: total_active_months + data_type: numeric + description: | + "Total number of active months for all accounts over the last 12 months." + data_tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: expected_mrr + data_type: numeric + description: | + "Expected MRR for each new deal." + data_tests: + - not_null