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