From bb9dea8ed6c398c3cf29f062ef4f71a5809a0eca Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Thu, 30 Jan 2025 16:18:29 +0100 Subject: [PATCH] Removed changes for cutoff date --- ...is_date_before_previous_month_fixed_20.sql | 30 ------------------- .../int_monthly_onboarding_mrr_per_deal.sql | 12 +++++--- models/intermediate/cross/schema.yml | 7 +++-- .../general/mtd_aggregated_metrics.sql | 2 +- 4 files changed, 14 insertions(+), 37 deletions(-) delete mode 100644 macros/is_date_before_previous_month_fixed_20.sql diff --git a/macros/is_date_before_previous_month_fixed_20.sql b/macros/is_date_before_previous_month_fixed_20.sql deleted file mode 100644 index e66810e..0000000 --- a/macros/is_date_before_previous_month_fixed_20.sql +++ /dev/null @@ -1,30 +0,0 @@ -/* -This macro provides a boolean answer to the question: -- Is this date before the previous month? -- When the current day is before the 20th of the month, it returns: - - False for both the current and previous month. -- When the current day is the 20th or later, it returns: - - False only for the current month. - -Inputs: - - date: the date to check -Output: - - boolean; true if the date is before the previous month - false if the date is within the current or previous month - (with special handling for the 20th or later of the month) -*/ -{% macro is_date_before_previous_month_fixed_20(date) %} - ( - case - -- If today is the 20th or later, only exclude current month - when extract(day from now()) >= 20 - then - date_trunc('month', ({{ date }})::date)::date - < date_trunc('month', now())::date - -- If today is before the 20th, exclude both current and previous month - else - date_trunc('month', ({{ date }})::date)::date - < date_trunc('month', now() - interval '1 month')::date - end - ) -{% endmacro %} diff --git a/models/intermediate/cross/int_monthly_onboarding_mrr_per_deal.sql b/models/intermediate/cross/int_monthly_onboarding_mrr_per_deal.sql index 3066027..be29b55 100644 --- a/models/intermediate/cross/int_monthly_onboarding_mrr_per_deal.sql +++ b/models/intermediate/cross/int_monthly_onboarding_mrr_per_deal.sql @@ -1,6 +1,10 @@ with int_monthly_aggregated_metrics_history_by_deal as ( - select * from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }} + select + *, + (date_trunc('month', date) + interval '2 month' - interval '1 day')::date + as next_month_end_date + from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }} ), int_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}), deal_attributes as ( @@ -20,7 +24,7 @@ with ) -- Calculate expected MRR per deal by each dimension select - (date_trunc('month', m.date) + interval '2 month' - interval '1 day')::date as date, + m.next_month_end_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 @@ -36,7 +40,7 @@ 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, + m.next_month_end_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 @@ -52,7 +56,7 @@ 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, + m.next_month_end_date as date, 'global' as dimension, 'global' as dimension_value, sum(coalesce(m.total_revenue_in_gbp, 0)) / count(*) as expected_mrr_per_deal diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index 3238b6b..5149fac 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1712,8 +1712,11 @@ models: "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 previous months and dividing it by the number - of active months for each account." + active accounts over the last 12 previous months (before the ongoing month) + and dividing it by the number of active months for each account during this + period. + For example in December 2023 we will calculate the Onboarding MRR for a deal + using the revenue from December 2022 to November 2023." data_tests: - dbt_utils.unique_combination_of_columns: diff --git a/models/reporting/general/mtd_aggregated_metrics.sql b/models/reporting/general/mtd_aggregated_metrics.sql index bc3f1fb..427fb15 100644 --- a/models/reporting/general/mtd_aggregated_metrics.sql +++ b/models/reporting/general/mtd_aggregated_metrics.sql @@ -70,7 +70,7 @@ where or lower(metric) like '%retained%' or lower(metric) like '%damage host%' ) - and {{ is_date_before_previous_month_fixed_20("date") }} + and {{ is_date_before_previous_month("date") }} ) -- Not show current month if the metric is Expected MRR, unlike other -- revenue metrics, Expected MRR is calculated for the next month, so it is not