From 26898322e73cf3bb0ef3cef8e4441f9346af000c Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Wed, 29 Jan 2025 10:05:41 +0100 Subject: [PATCH] wip fixing deals from hubspot --- .../int_monthly_onboarding_mrr_metrics.sql | 63 ----------------- .../int_monthly_onboarding_mrr_per_deal.sql | 67 +++++++++++++++++++ .../int_mtd_agg_onboarding_mrr_metrics.sql | 67 ------------------- .../int_mtd_agg_onboarding_mrr_revenue.sql | 31 +++++++++ .../int_mtd_vs_previous_year_metrics.sql | 59 +++++++--------- models/intermediate/cross/schema.yml | 62 +++++------------ 6 files changed, 136 insertions(+), 213 deletions(-) delete mode 100644 models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql create mode 100644 models/intermediate/cross/int_monthly_onboarding_mrr_per_deal.sql delete mode 100644 models/intermediate/cross/int_mtd_agg_onboarding_mrr_metrics.sql create mode 100644 models/intermediate/cross/int_mtd_agg_onboarding_mrr_revenue.sql diff --git a/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql deleted file mode 100644 index fbee173..0000000 --- a/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql +++ /dev/null @@ -1,63 +0,0 @@ -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 diff --git a/models/intermediate/cross/int_monthly_onboarding_mrr_per_deal.sql b/models/intermediate/cross/int_monthly_onboarding_mrr_per_deal.sql new file mode 100644 index 0000000..9f5181c --- /dev/null +++ b/models/intermediate/cross/int_monthly_onboarding_mrr_per_deal.sql @@ -0,0 +1,67 @@ +with + int_monthly_aggregated_metrics_history_by_deal as ( + select * from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }} + ), + 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 + ) +-- Calculate expected MRR per deal by each dimension +select + m.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 + m.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 + m.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 diff --git a/models/intermediate/cross/int_mtd_agg_onboarding_mrr_metrics.sql b/models/intermediate/cross/int_mtd_agg_onboarding_mrr_metrics.sql deleted file mode 100644 index 1f02314..0000000 --- a/models/intermediate/cross/int_mtd_agg_onboarding_mrr_metrics.sql +++ /dev/null @@ -1,67 +0,0 @@ -with - int_kpis__agg_daily_deals as ( - select date, dimension_value as hubspot_listing_segmentation, new_deals - from {{ ref("int_kpis__agg_daily_deals") }} - where dimension = 'by_number_of_listings' - ), - onboarding_mrr_metrics as ( - select - mom.date, - 'by_number_of_listings' as dimension, - mom.hubspot_listing_segmentation as dimension_value, - ad.number_of_new_deals, - mom.expected_mrr as expected_mrr_per_deal, - mom.expected_mrr * ad.number_of_new_deals as expected_mrr - from {{ ref("int_monthly_onboarding_mrr_metrics") }} mom - left join - int_kpis__agg_daily_deals ad - on mom.date = ad.date - and mom.hubspot_listing_segmentation = ad.hubspot_listing_segmentation - where - mom.main_billing_country_iso_3 = 'global' - and mom.hubspot_listing_segmentation <> 'global' - union all - select - date, - 'by_billing_country' as dimension, - main_billing_country_iso_3 as dimension_value, - null as number_of_new_deals, - expected_mrr as expected_mrr_per_deal, - null as expected_mrr - from {{ ref("int_monthly_onboarding_mrr_metrics") }} - where - hubspot_listing_segmentation = 'global' - and main_billing_country_iso_3 <> 'global' - union all - select - date, - 'global' as dimension, - 'global' as dimension_value, - null as number_of_new_deals, - expected_mrr as expected_mrr_per_deal, - null as expected_mrr - from {{ ref("int_monthly_onboarding_mrr_metrics") }} - where - hubspot_listing_segmentation = 'global' - and main_billing_country_iso_3 = 'global' - ), - global_expected_mrr as ( - select - omm.date, - 'global' as dimension, - sum(omm.number_of_new_deals) as number_of_new_deals, - sum(omm.number_of_new_deals * omm.expected_mrr_per_deal) as expected_mrr - from onboarding_mrr_metrics omm - where omm.dimension = 'by_number_of_listings' - group by 1, 2 - ) -select - omm.date, - omm.dimension, - omm.dimension_value, - coalesce(gem.number_of_new_deals, omm.number_of_new_deals) as number_of_new_deals, - omm.expected_mrr_per_deal, - coalesce(gem.expected_mrr, omm.expected_mrr) as expected_mrr -from onboarding_mrr_metrics omm -left join - global_expected_mrr gem on omm.date = gem.date and omm.dimension = gem.dimension diff --git a/models/intermediate/cross/int_mtd_agg_onboarding_mrr_revenue.sql b/models/intermediate/cross/int_mtd_agg_onboarding_mrr_revenue.sql new file mode 100644 index 0000000..f57c266 --- /dev/null +++ b/models/intermediate/cross/int_mtd_agg_onboarding_mrr_revenue.sql @@ -0,0 +1,31 @@ +with + int_kpis__agg_daily_deals as ( + select date, dimension_value as hubspot_listing_segmentation, new_deals + from {{ ref("int_kpis__agg_daily_deals") }} + where dimension = 'by_number_of_listings' + ), + number_of_listing_expected_mrr as ( + select + mom.date, + mom.dimension, + mom.dimension_value, + ad.new_deals as number_of_new_deals, + mom.expected_mrr_per_deal * ad.new_deals as expected_mrr + from {{ ref("int_monthly_onboarding_mrr_per_deal") }} mom + left join + int_kpis__agg_daily_deals ad + on mom.date = ad.date + and mom.dimension_value = ad.hubspot_listing_segmentation + where mom.dimension = 'by_number_of_listings' + ) +select * +from number_of_listing_expected_mrr +union all +select + date, + 'global' as dimension, + 'global' as dimension_value, + sum(number_of_new_deals) as number_of_new_deals, + sum(expected_mrr) as expected_mrr +from number_of_listing_expected_mrr +group by date diff --git a/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql b/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql index e74653a..fbaf717 100644 --- a/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql +++ b/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql @@ -171,8 +171,11 @@ with dimension in ('global', 'by_number_of_listings', 'by_billing_country') and dimension_value <> 'UNSET' ), - int_mtd_agg_onboarding_mrr_metrics as ( - select * from {{ ref("int_mtd_agg_onboarding_mrr_metrics") }} + int_monthly_onboarding_mrr_per_deal as ( + select * from {{ ref("int_monthly_onboarding_mrr_per_deal") }} + ), + int_mtd_agg_onboarding_mrr_revenue as ( + select * from {{ ref("int_mtd_agg_onboarding_mrr_revenue") }} ), plain_kpi_combination as ( @@ -266,10 +269,9 @@ with as host_resolution_amount_paid_per_created_booking, {{ return_capped_value( - "cast(host_resolutions.xero_host_resolution_payment_count as decimal) - / created_bookings.created_bookings", + "cast(host_resolutions.xero_host_resolution_payment_count as decimal) / created_bookings.created_bookings", -1, - 1 + 1, ) }} as host_resolution_payment_per_created_booking_ratio, @@ -347,21 +349,12 @@ with ) as revenue_retained_in_gbp, {{ return_capped_value( - "nullif( - coalesce(guest_payments.total_guest_payments_in_gbp, 0) - + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) - + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) - + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0), - 0 - ) / nullif( - coalesce(guest_payments.total_guest_payments_in_gbp, 0) - + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) - + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0), - 0 - )", + "nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0), 0 ) / nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0), 0 )", -1, - 1 - )}} as revenue_retained_ratio, + 1, + ) + }} + as revenue_retained_ratio, -- INCOME RETAINED POST RESOLUTIONS-- nullif( @@ -374,27 +367,16 @@ with ) as revenue_retained_post_resolutions_in_gbp, {{ return_capped_value( - "nullif( - coalesce(guest_payments.total_guest_payments_in_gbp, 0) - + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) - + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) - + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0) - + coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0), - 0 - ) / nullif( - coalesce(guest_payments.total_guest_payments_in_gbp, 0) - + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) - + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0), - 0 - )", + "nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0) + coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0), 0 ) / nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0), 0 )", -1, - 1 + 1, ) - }} as revenue_retained_post_resolutions_ratio, + }} + as revenue_retained_post_resolutions_ratio, -- ONBOARDING MRR METRIC -- onboarding_mrr.expected_mrr_per_deal, - onboarding_mrr.expected_mrr + onboarding_mrr_revenue.expected_mrr from int_kpis__agg_dates_main_kpis d left join @@ -468,10 +450,15 @@ with and d.dimension = churn.dimension and d.dimension_value = churn.dimension_value left join - int_mtd_agg_onboarding_mrr_metrics onboarding_mrr + int_monthly_onboarding_mrr_per_deal onboarding_mrr on d.date = onboarding_mrr.date and d.dimension = onboarding_mrr.dimension and d.dimension_value = onboarding_mrr.dimension_value + left join + int_mtd_agg_onboarding_mrr_revenue onboarding_mrr_revenue + on d.date = onboarding_mrr_revenue.date + and d.dimension = onboarding_mrr_revenue.dimension + and d.dimension_value = onboarding_mrr_revenue.dimension_value ) select diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index 71cac76..419ed66 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1707,7 +1707,7 @@ models: data_type: boolean description: "Flag to indicate if the deal is in Xero." - - name: int_monthly_onboarding_mrr_metrics + - name: int_monthly_onboarding_mrr_per_deal 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 @@ -1719,68 +1719,40 @@ models: - dbt_utils.unique_combination_of_columns: combination_of_columns: - date - - main_billing_country_iso_3 - - hubspot_listing_segmentation + - dimension + - dimension_value 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" + description: The date for the month-to-date metrics. 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." + - name: dimension + data_type: string + description: The dimension or granularity of the metrics. data_tests: - - not_null - accepted_values: values: - - "01-05" - - "06-20" - - "21-60" - - "61+" - - "global" + - global + - by_number_of_listings + - by_billing_country - - name: total_revenue_in_gbp - data_type: numeric - description: | - "Total revenue accumulated by all active accounts over the last 12 months." + - name: dimension_value + data_type: string + description: The value or segment available for the selected dimension. 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 + - name: expected_mrr_per_deal data_type: numeric description: | "Expected MRR for each new deal." data_tests: - not_null - - name: int_mtd_agg_onboarding_mrr_metrics + - name: int_mtd_agg_onboarding_mrr_revenue description: | This model contains the month-to-date aggregated metrics for the onboarding MRR. It includes the expected MRR per deal and the total expected MRR, which is obtained @@ -1820,10 +1792,6 @@ models: data_type: numeric description: Number of new deals in the month. - - name: expected_mrr_per_deal - data_type: numeric - description: Expected Onboarding MRR per new deal. - - name: expected_mrr data_type: numeric description: |