From 92c0574374dc5b05911c299bc805e12c8eec7f5e Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 13 Jan 2025 12:34:09 +0100 Subject: [PATCH 1/8] commit uri's query --- .../cross/int_onboarding_mrr_by_segment.sql | 153 ++++++++++++++++++ 1 file changed, 153 insertions(+) create mode 100644 models/intermediate/cross/int_onboarding_mrr_by_segment.sql diff --git a/models/intermediate/cross/int_onboarding_mrr_by_segment.sql b/models/intermediate/cross/int_onboarding_mrr_by_segment.sql new file mode 100644 index 0000000..d1e6849 --- /dev/null +++ b/models/intermediate/cross/int_onboarding_mrr_by_segment.sql @@ -0,0 +1,153 @@ +with + deal_attributes as ( + select + id_deal, + date_trunc('month', live_date_utc)::date as live_month, + date_trunc('month', cancellation_date_utc)::date as cancellation_month, + amount_of_properties, + case + when amount_of_properties between 1 and 5 + then '01|05' + when amount_of_properties between 6 and 20 + then '06|20' + when amount_of_properties between 21 and 60 + then '21|60' + when amount_of_properties >= 61 + then '61+' + else 'UNSET' + end as property_bucket + from {{ ref("int_hubspot__deal") }} ihd + where live_date_utc is not null -- exclude deals that do not have live date + ), + deal_revenue_attribution_on_live_month as ( + select + d.id_deal, + d.live_month, + d.cancellation_month, + d.amount_of_properties, + d.property_bucket, + sum( + case + when + date_trunc('month', m.date)::date + < live_month + interval '12 months' + then coalesce(m.total_revenue_in_gbp, 0) + else 0 + end + ) as deal_total_revenue_first_12_months_in_gbp, + sum( + case + when + date_trunc('month', m.date)::date + < live_month + interval '12 months' + then 1 + else 0 + end + ) as deal_active_months_first_12_months, + sum( + coalesce(m.total_revenue_in_gbp, 0) + ) as deal_total_revenue_all_history_in_gbp, + sum(1) as deal_active_months_all_history + 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) >= d.live_month + and date_trunc('month', m.date) + <= coalesce(d.cancellation_month, '2099-01-01') + -- Exclude current month due to incomplete Revenue data + and date_trunc('month', m.date)::date <> date_trunc('month', now())::date + group by + d.id_deal, + d.live_month, + d.cancellation_month, + d.amount_of_properties, + d.property_bucket + ), + agg_revenue_attribution_on_metric_month as ( + select + date_trunc('month', m.date)::date as metric_month, + coalesce(d.property_bucket, 'global') as property_bucket, + count(1) 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) >= d.live_month + and date_trunc('month', m.date) + <= coalesce(d.cancellation_month, '2099-01-01') + -- Exclude current month due to incomplete Revenue data + and date_trunc('month', m.date)::date <> date_trunc('month', now())::date + where d.property_bucket <> 'UNSET' + group by rollup (1, d.property_bucket) + -- Remove global live month after roll-up + having date_trunc('month', m.date)::date is not null + order by 1 desc, 2 desc + ), + real_revenue_per_property_bucket_and_live_month as ( + select + live_month, + coalesce(property_bucket, 'global') as property_bucket, + count(id_deal) as deals_live_in_month, + sum( + deal_total_revenue_first_12_months_in_gbp + ) as total_revenue_first_12_months_in_gbp, + sum( + deal_total_revenue_all_history_in_gbp + ) as total_revenue_all_history_in_gbp, + sum( + deal_active_months_first_12_months + ) as total_active_months_first_12_months, + sum(deal_active_months_all_history) as total_active_months_all_history, + sum(deal_total_revenue_first_12_months_in_gbp) / sum( + deal_active_months_first_12_months + ) as real_weighted_avg_total_revenue_first_12_months, + sum(deal_total_revenue_all_history_in_gbp) / sum( + deal_active_months_all_history + ) as real_weighted_avg_total_revenue_all_history + from deal_revenue_attribution_on_live_month + -- In some extreme cases, a Deal can be onboarded but have no backend activity + -- for the next 12 months, and have it later on + -- The following condition removes these deals to avoid computation errors. + where + deal_active_months_first_12_months > 0 + -- Remove Unset, those deals that do not have the amount of properties + -- informed + and property_bucket <> 'UNSET' + group by rollup (live_month, property_bucket) + -- Remove global live month after roll-up + having live_month is not null + ), + method_two_monthly_revenue_per_bucket_last_12_months as ( + select + r.metric_month, + r.property_bucket as property_bucket, + sum(coalesce(m.total_revenue_in_gbp, 0)) as cumulative_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_per_month + from agg_revenue_attribution_on_metric_month m + inner join + agg_revenue_attribution_on_metric_month r + on r.metric_month > m.metric_month + and r.metric_month <= m.metric_month + interval '12 months' + and r.property_bucket = m.property_bucket + group by 1, 2 + ) +select + case + when r.live_month + interval '12 months' >= date_trunc('month', now())::date + then 1 + else 0 + end as is_not_full_12_months_period, + r.live_month as metric_month, + r.property_bucket, + r.real_weighted_avg_total_revenue_all_history, + m2.expected_mrr_per_month as m1_expected_mrr_per_month +from real_revenue_per_property_bucket_and_live_month r +left join + method_two_monthly_revenue_per_bucket_last_12_months m2 + on r.live_month = m2.metric_month + and r.property_bucket = m2.property_bucket +order by r.live_month desc, r.property_bucket desc From d0406e975a377dfcf2430f362ed779e59a2e3820 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 13 Jan 2025 16:11:19 +0100 Subject: [PATCH 2/8] commit wip to rebase --- .../cross/int_onboarding_mrr_by_segment.sql | 136 +++--------------- 1 file changed, 21 insertions(+), 115 deletions(-) diff --git a/models/intermediate/cross/int_onboarding_mrr_by_segment.sql b/models/intermediate/cross/int_onboarding_mrr_by_segment.sql index d1e6849..306b7d9 100644 --- a/models/intermediate/cross/int_onboarding_mrr_by_segment.sql +++ b/models/intermediate/cross/int_onboarding_mrr_by_segment.sql @@ -17,58 +17,14 @@ with else 'UNSET' end as property_bucket from {{ ref("int_hubspot__deal") }} ihd - where live_date_utc is not null -- exclude deals that do not have live date + -- Exclude deals without live dates + where live_date_utc is not null ), - deal_revenue_attribution_on_live_month as ( - select - d.id_deal, - d.live_month, - d.cancellation_month, - d.amount_of_properties, - d.property_bucket, - sum( - case - when - date_trunc('month', m.date)::date - < live_month + interval '12 months' - then coalesce(m.total_revenue_in_gbp, 0) - else 0 - end - ) as deal_total_revenue_first_12_months_in_gbp, - sum( - case - when - date_trunc('month', m.date)::date - < live_month + interval '12 months' - then 1 - else 0 - end - ) as deal_active_months_first_12_months, - sum( - coalesce(m.total_revenue_in_gbp, 0) - ) as deal_total_revenue_all_history_in_gbp, - sum(1) as deal_active_months_all_history - 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) >= d.live_month - and date_trunc('month', m.date) - <= coalesce(d.cancellation_month, '2099-01-01') - -- Exclude current month due to incomplete Revenue data - and date_trunc('month', m.date)::date <> date_trunc('month', now())::date - group by - d.id_deal, - d.live_month, - d.cancellation_month, - d.amount_of_properties, - d.property_bucket - ), - agg_revenue_attribution_on_metric_month as ( + monthly_revenue_per_property_bucket as ( select date_trunc('month', m.date)::date as metric_month, coalesce(d.property_bucket, 'global') as property_bucket, - count(1) as deals_active_in_month, + 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 @@ -77,77 +33,27 @@ with and date_trunc('month', m.date) >= d.live_month and date_trunc('month', m.date) <= coalesce(d.cancellation_month, '2099-01-01') - -- Exclude current month due to incomplete Revenue data and date_trunc('month', m.date)::date <> date_trunc('month', now())::date where d.property_bucket <> 'UNSET' - group by rollup (1, d.property_bucket) - -- Remove global live month after roll-up + group by rollup (date_trunc('month', m.date)::date, d.property_bucket) having date_trunc('month', m.date)::date is not null - order by 1 desc, 2 desc - ), - real_revenue_per_property_bucket_and_live_month as ( - select - live_month, - coalesce(property_bucket, 'global') as property_bucket, - count(id_deal) as deals_live_in_month, - sum( - deal_total_revenue_first_12_months_in_gbp - ) as total_revenue_first_12_months_in_gbp, - sum( - deal_total_revenue_all_history_in_gbp - ) as total_revenue_all_history_in_gbp, - sum( - deal_active_months_first_12_months - ) as total_active_months_first_12_months, - sum(deal_active_months_all_history) as total_active_months_all_history, - sum(deal_total_revenue_first_12_months_in_gbp) / sum( - deal_active_months_first_12_months - ) as real_weighted_avg_total_revenue_first_12_months, - sum(deal_total_revenue_all_history_in_gbp) / sum( - deal_active_months_all_history - ) as real_weighted_avg_total_revenue_all_history - from deal_revenue_attribution_on_live_month - -- In some extreme cases, a Deal can be onboarded but have no backend activity - -- for the next 12 months, and have it later on - -- The following condition removes these deals to avoid computation errors. - where - deal_active_months_first_12_months > 0 - -- Remove Unset, those deals that do not have the amount of properties - -- informed - and property_bucket <> 'UNSET' - group by rollup (live_month, property_bucket) - -- Remove global live month after roll-up - having live_month is not null - ), - method_two_monthly_revenue_per_bucket_last_12_months as ( - select - r.metric_month, - r.property_bucket as property_bucket, - sum(coalesce(m.total_revenue_in_gbp, 0)) as cumulative_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_per_month - from agg_revenue_attribution_on_metric_month m - inner join - agg_revenue_attribution_on_metric_month r - on r.metric_month > m.metric_month - and r.metric_month <= m.metric_month + interval '12 months' - and r.property_bucket = m.property_bucket - group by 1, 2 ) select + r.metric_month, case - when r.live_month + interval '12 months' >= date_trunc('month', now())::date - then 1 - else 0 - end as is_not_full_12_months_period, - r.live_month as metric_month, + when r.metric_month + interval '12 months' >= date_trunc('month', now())::date + then 0 + else 1 + end as is_full_12_months_period, r.property_bucket, - r.real_weighted_avg_total_revenue_all_history, - m2.expected_mrr_per_month as m1_expected_mrr_per_month -from real_revenue_per_property_bucket_and_live_month r -left join - method_two_monthly_revenue_per_bucket_last_12_months m2 - on r.live_month = m2.metric_month - and r.property_bucket = m2.property_bucket -order by r.live_month desc, r.property_bucket desc + sum(coalesce(m.total_revenue_in_gbp, 0)) as cumulative_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_per_month +from monthly_revenue_per_property_bucket m +inner join + monthly_revenue_per_property_bucket r + on r.metric_month > m.metric_month + and r.metric_month <= m.metric_month + interval '12 months' + and r.property_bucket = m.property_bucket +group by r.metric_month, is_full_12_months_period, r.property_bucket From 77a70d21a4214a7dd108142bb8188509d90c4b0f Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 13 Jan 2025 17:26:34 +0100 Subject: [PATCH 3/8] commit wip schema --- .../cross/int_onboarding_mrr_by_segment.sql | 4 +- models/intermediate/cross/schema.yml | 48 +++++++++++++++++++ 2 files changed, 50 insertions(+), 2 deletions(-) diff --git a/models/intermediate/cross/int_onboarding_mrr_by_segment.sql b/models/intermediate/cross/int_onboarding_mrr_by_segment.sql index 306b7d9..add3c0f 100644 --- a/models/intermediate/cross/int_onboarding_mrr_by_segment.sql +++ b/models/intermediate/cross/int_onboarding_mrr_by_segment.sql @@ -42,8 +42,8 @@ select r.metric_month, case when r.metric_month + interval '12 months' >= date_trunc('month', now())::date - then 0 - else 1 + then false + else true end as is_full_12_months_period, r.property_bucket, sum(coalesce(m.total_revenue_in_gbp, 0)) as cumulative_total_revenue_in_gbp, diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index 6daf234..d368381 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1706,3 +1706,51 @@ models: - name: is_deal_in_xero data_type: boolean description: "Flag to indicate if the deal is in Xero." + + - name: int_onboarding_mrr_by_segment + description: | + "This table provides data on the Onboarding Monthly Recurring Revenue (MRR), + segmented by the number of properties specified in each deal on HubSpot. + 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." + columns: + - name: date + data_type: date + description: | + "Date from which the data is being taken. It is the first day of the month." + + - name: is_full_12_months_period + data_type: boolean + description: | + "Boolean that indicates if there is a full 12 months period of data." + + - name: property_bucket + data_type: text + description: | + "Segmentation based on the number of properties specified by each deal + in HubSpot." + data_tests: + - accepted_values: + values: + - "01|05" + - "06|20" + - "21|60" + - "61+" + - "global" + + - name: cumulative_total_revenue_in_gbp + data_type: numeric + description: | + "Total revenue revenue + + - name: total_active_months + data_type: numeric + description: | + "D + + - name: expected_mrr_per_month + data_type: numeric + description: | + "D From 1db8a050ceaa3b39ef5265b4c6b94a74c70842a4 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Tue, 14 Jan 2025 11:48:44 +0100 Subject: [PATCH 4/8] creates onboarding mrr model --- ...gment.sql => int_deals_onboarding_mrr.sql} | 34 +++++++++------ models/intermediate/cross/schema.yml | 41 +++++++++++++------ 2 files changed, 49 insertions(+), 26 deletions(-) rename models/intermediate/cross/{int_onboarding_mrr_by_segment.sql => int_deals_onboarding_mrr.sql} (66%) diff --git a/models/intermediate/cross/int_onboarding_mrr_by_segment.sql b/models/intermediate/cross/int_deals_onboarding_mrr.sql similarity index 66% rename from models/intermediate/cross/int_onboarding_mrr_by_segment.sql rename to models/intermediate/cross/int_deals_onboarding_mrr.sql index add3c0f..9559da3 100644 --- a/models/intermediate/cross/int_onboarding_mrr_by_segment.sql +++ b/models/intermediate/cross/int_deals_onboarding_mrr.sql @@ -1,10 +1,12 @@ with deal_attributes as ( select - id_deal, + ihd.id_deal, date_trunc('month', live_date_utc)::date as live_month, date_trunc('month', cancellation_date_utc)::date as cancellation_month, - amount_of_properties, + coalesce( + icd.main_billing_country_iso_3_per_deal, 'UNSET' + ) as main_billing_country_iso_3_per_deal, case when amount_of_properties between 1 and 5 then '01|05' @@ -17,12 +19,16 @@ with else 'UNSET' end as property_bucket from {{ ref("int_hubspot__deal") }} ihd + left join {{ ref("int_core__deal") }} icd on ihd.id_deal = icd.id_deal -- Exclude deals without live dates where live_date_utc is not null ), monthly_revenue_per_property_bucket as ( select date_trunc('month', m.date)::date as metric_month, + coalesce( + d.main_billing_country_iso_3_per_deal, 'global' + ) as main_billing_country_iso_3, coalesce(d.property_bucket, 'global') as property_bucket, count(*) as deals_active_in_month, sum(coalesce(m.total_revenue_in_gbp, 0)) as total_revenue_in_gbp @@ -35,25 +41,27 @@ with <= coalesce(d.cancellation_month, '2099-01-01') and date_trunc('month', m.date)::date <> date_trunc('month', now())::date where d.property_bucket <> 'UNSET' - group by rollup (date_trunc('month', m.date)::date, d.property_bucket) + group by + rollup ( + date_trunc('month', m.date)::date, + d.property_bucket, + d.main_billing_country_iso_3_per_deal + ) having date_trunc('month', m.date)::date is not null ) select - r.metric_month, - case - when r.metric_month + interval '12 months' >= date_trunc('month', now())::date - then false - else true - end as is_full_12_months_period, - r.property_bucket, - sum(coalesce(m.total_revenue_in_gbp, 0)) as cumulative_total_revenue_in_gbp, + (r.metric_month - interval '1 day')::date as date, + r.main_billing_country_iso_3 as billing_country, + r.property_bucket as number_of_listings, + 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_per_month + / sum(m.deals_active_in_month) as expected_mrr from monthly_revenue_per_property_bucket m inner join monthly_revenue_per_property_bucket r on r.metric_month > m.metric_month and r.metric_month <= m.metric_month + interval '12 months' and r.property_bucket = m.property_bucket -group by r.metric_month, is_full_12_months_period, r.property_bucket + and r.main_billing_country_iso_3 = m.main_billing_country_iso_3 +group by r.metric_month, r.property_bucket, r.main_billing_country_iso_3 diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index d368381..3658d0e 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1707,10 +1707,9 @@ models: data_type: boolean description: "Flag to indicate if the deal is in Xero." - - name: int_onboarding_mrr_by_segment + - name: int_deals_onboarding_mrr description: | - "This table provides data on the Onboarding Monthly Recurring Revenue (MRR), - segmented by the number of properties specified in each deal on HubSpot. + "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 @@ -1719,19 +1718,26 @@ models: - name: date data_type: date description: | - "Date from which the data is being taken. It is the first day of the month." + "Last date of the month for which the data is reported. + It considers the data from the previous 12 months up to the date." + data_tests: + - not_null + - is_last_day_of_month - - name: is_full_12_months_period - data_type: boolean + - name: billing_country + data_type: text description: | - "Boolean that indicates if there is a full 12 months period of data." + "ISO 3166-1 alpha-3 main country code in which the Deals are billed" + data_tests: + - not_null - - name: property_bucket + - name: number_of_listings 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" @@ -1740,17 +1746,26 @@ models: - "61+" - "global" - - name: cumulative_total_revenue_in_gbp + - name: total_revenue_in_gbp data_type: numeric description: | - "Total revenue revenue + "Total revenue accumulated by all active accounts over the last 12 months." + data_tests: + - not_null - name: total_active_months data_type: numeric description: | - "D + "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_per_month + - name: expected_mrr data_type: numeric description: | - "D + "Expected MRR for each new deal." + data_tests: + - not_null From b0634544095907a13ac95ad86daedaba4ea21694 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Tue, 14 Jan 2025 16:42:49 +0100 Subject: [PATCH 5/8] commit wip --- .../cross/int_deals_onboarding_mrr.sql | 67 ------------------- .../int_monthly_onboarding_mrr_metrics.sql | 51 ++++++++++++++ models/intermediate/cross/schema.yml | 12 ++-- 3 files changed, 57 insertions(+), 73 deletions(-) delete mode 100644 models/intermediate/cross/int_deals_onboarding_mrr.sql create mode 100644 models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql diff --git a/models/intermediate/cross/int_deals_onboarding_mrr.sql b/models/intermediate/cross/int_deals_onboarding_mrr.sql deleted file mode 100644 index 9559da3..0000000 --- a/models/intermediate/cross/int_deals_onboarding_mrr.sql +++ /dev/null @@ -1,67 +0,0 @@ -with - deal_attributes as ( - select - ihd.id_deal, - date_trunc('month', live_date_utc)::date as live_month, - date_trunc('month', cancellation_date_utc)::date as cancellation_month, - coalesce( - icd.main_billing_country_iso_3_per_deal, 'UNSET' - ) as main_billing_country_iso_3_per_deal, - case - when amount_of_properties between 1 and 5 - then '01|05' - when amount_of_properties between 6 and 20 - then '06|20' - when amount_of_properties between 21 and 60 - then '21|60' - when amount_of_properties >= 61 - then '61+' - else 'UNSET' - end as property_bucket - from {{ ref("int_hubspot__deal") }} ihd - left join {{ ref("int_core__deal") }} icd on ihd.id_deal = icd.id_deal - -- Exclude deals without live dates - where live_date_utc is not null - ), - monthly_revenue_per_property_bucket as ( - select - date_trunc('month', m.date)::date as metric_month, - coalesce( - d.main_billing_country_iso_3_per_deal, 'global' - ) as main_billing_country_iso_3, - coalesce(d.property_bucket, 'global') as property_bucket, - 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) >= d.live_month - and date_trunc('month', m.date) - <= coalesce(d.cancellation_month, '2099-01-01') - and date_trunc('month', m.date)::date <> date_trunc('month', now())::date - where d.property_bucket <> 'UNSET' - group by - rollup ( - date_trunc('month', m.date)::date, - d.property_bucket, - d.main_billing_country_iso_3_per_deal - ) - having date_trunc('month', m.date)::date is not null - ) -select - (r.metric_month - interval '1 day')::date as date, - r.main_billing_country_iso_3 as billing_country, - r.property_bucket as number_of_listings, - 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_property_bucket m -inner join - monthly_revenue_per_property_bucket r - on r.metric_month > m.metric_month - and r.metric_month <= m.metric_month + interval '12 months' - and r.property_bucket = m.property_bucket - and r.main_billing_country_iso_3 = m.main_billing_country_iso_3 -group by r.metric_month, r.property_bucket, r.main_billing_country_iso_3 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..edb93c2 --- /dev/null +++ b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql @@ -0,0 +1,51 @@ +with + deal_attributes as ( + select * + 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 + date_trunc('month', m.date)::date as metric_month, + 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) >= d.effective_deal_start_month + and date_trunc('month', m.date) + <= coalesce(d.effective_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 ( + date_trunc('month', m.date)::date, + d.hubspot_listing_segmentation, + d.main_billing_country_iso_3_per_deal + ) + having date_trunc('month', m.date)::date is not null + ) +select + (r.metric_month - interval '1 day')::date as 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.metric_month > m.metric_month + and r.metric_month <= m.metric_month + 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 +group by r.metric_month, 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 3658d0e..df08619 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_deals_onboarding_mrr + - 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 @@ -1724,14 +1724,14 @@ models: - not_null - is_last_day_of_month - - name: billing_country + - name: main_billing_country_iso_3 data_type: text description: | "ISO 3166-1 alpha-3 main country code in which the Deals are billed" data_tests: - not_null - - name: number_of_listings + - name: hubspot_listing_segmentation data_type: text description: | "Segmentation based on the number of properties specified by each deal @@ -1740,9 +1740,9 @@ models: - not_null - accepted_values: values: - - "01|05" - - "06|20" - - "21|60" + - "01-05" + - "06-20" + - "21-60" - "61+" - "global" From 261c6d3c49e834d04c00fa320abcc501a16c5a65 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Wed, 15 Jan 2025 12:03:25 +0100 Subject: [PATCH 6/8] Updated logic of model --- .../cross/int_monthly_onboarding_mrr_metrics.sql | 15 ++++++++------- models/intermediate/cross/schema.yml | 16 +++++++++++++--- 2 files changed, 21 insertions(+), 10 deletions(-) diff --git a/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql index edb93c2..71c3cf8 100644 --- a/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql +++ b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql @@ -7,7 +7,7 @@ with ), monthly_revenue_per_number_of_properties as ( select - date_trunc('month', m.date)::date as metric_month, + m.date as metric_month, coalesce( d.main_billing_country_iso_3_per_deal, 'global' ) as main_billing_country_iso_3, @@ -22,19 +22,20 @@ with on m.id_deal = d.id_deal and date_trunc('month', m.date) >= d.effective_deal_start_month and date_trunc('month', m.date) - <= coalesce(d.effective_deal_cancellation_month, '2099-01-01') + <= 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 ( - date_trunc('month', m.date)::date, + m.date, d.hubspot_listing_segmentation, d.main_billing_country_iso_3_per_deal ) - having date_trunc('month', m.date)::date is not null + -- Exclude total date aggregation + having m.date is not null ) select - (r.metric_month - interval '1 day')::date as date, + r.metric_month as date, r.main_billing_country_iso_3, r.hubspot_listing_segmentation, sum(coalesce(m.total_revenue_in_gbp, 0)) as total_revenue_in_gbp, @@ -44,8 +45,8 @@ select from monthly_revenue_per_number_of_properties m inner join monthly_revenue_per_number_of_properties r - on r.metric_month > m.metric_month - and r.metric_month <= m.metric_month + interval '12 months' + on r.metric_month >= m.metric_month + and r.metric_month < m.metric_month + 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 group by r.metric_month, 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 df08619..a19a116 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1714,12 +1714,22 @@ models: 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: | - "Last date of the month for which the data is reported. - It considers the data from the previous 12 months up to the date." + "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 @@ -1727,7 +1737,7 @@ models: - name: main_billing_country_iso_3 data_type: text description: | - "ISO 3166-1 alpha-3 main country code in which the Deals are billed" + "Main billing country code from ISO 3166" data_tests: - not_null From 5bf2fba4cff1e05c76443d1da6bcd778afcadabf Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Wed, 15 Jan 2025 16:35:02 +0100 Subject: [PATCH 7/8] Found the issue that was excluding some deals --- .../int_monthly_onboarding_mrr_metrics.sql | 24 +++++++++++++------ 1 file changed, 17 insertions(+), 7 deletions(-) diff --git a/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql index 71c3cf8..a9a2280 100644 --- a/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql +++ b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql @@ -1,13 +1,22 @@ with deal_attributes as ( - select * + 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 as metric_month, + m.date, coalesce( d.main_billing_country_iso_3_per_deal, 'global' ) as main_billing_country_iso_3, @@ -20,7 +29,8 @@ with inner join deal_attributes d on m.id_deal = d.id_deal - and date_trunc('month', m.date) >= d.effective_deal_start_month + 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 @@ -35,7 +45,7 @@ with having m.date is not null ) select - r.metric_month as date, + 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, @@ -45,8 +55,8 @@ select from monthly_revenue_per_number_of_properties m inner join monthly_revenue_per_number_of_properties r - on r.metric_month >= m.metric_month - and r.metric_month < m.metric_month + interval '12 months' + 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 -group by r.metric_month, r.hubspot_listing_segmentation, r.main_billing_country_iso_3 +group by r.date, r.hubspot_listing_segmentation, r.main_billing_country_iso_3 From 095bfb8ab1d560c944ee4b4492c18f621d286768 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Thu, 16 Jan 2025 11:35:39 +0100 Subject: [PATCH 8/8] removed UNSET billing_countries --- models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql index a9a2280..f87589d 100644 --- a/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql +++ b/models/intermediate/cross/int_monthly_onboarding_mrr_metrics.sql @@ -59,4 +59,5 @@ inner join 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