Merged PR 4202: New expected MRR metric
# Description Sorry for this PR, it ended up having a lot of changes. I'll try to list them to make it as clear as possible. - **int_monthly_onboarding_mrr_per_deal: **This model was changed to obtain all values of `expected_onboarding_mrr_per_deal` for our used dimensions. - **int_mtd_agg_onboarding_mrr_revenue: **This model obtains the `expected_onboarding_mrr_revenue` for dimension `per_number_of_listings` and `global` which is obtained by adding the values from the first one. - **int_mtd_aggregated_metrics: ** Removed the `first_time_booked_deals` metric, renamed the `expected_mrr` to `expected_mrr_per_deal` and added `expected_mrr` for the total revenue expected - **int_mtd_vs_previous_year_metrics: ** removed the `first_time_booked_deals` metric and added the new MRR metrics. Changed how this was being computed, previously it was being done in this same model now it gets them directly from both onboarding_mrr models - **int_kpis__lifecycle_daily_deal: ** Included all deals in HubSpot and used the `live_date_utc` as the date when deals go live, unless the deal is not in HubSpot then it uses the `created_date_utc` from core - **int_kpis__metric_daily_deals: ** Changed the logic for `New Deals` so it uses `hubspot_listing_segmentation` instead of `active_accommodations_per_deal_segmentation` like the others states of the deal_lifecycle **the package-dock.yml need to rebase** # Checklist - [x] The edited models and dependants run properly with production data. - [x] The edited models are sufficiently documented. - [x] The edited models contain PK tests, and I've ran and passed them. - [ ] I have checked for DRY opportunities with other models and docs. - [ ] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. New expected MRR metric Related work items: #26820
This commit is contained in:
commit
62cecf52f0
8 changed files with 214 additions and 157 deletions
|
|
@ -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
|
|
||||||
|
|
@ -0,0 +1,68 @@
|
||||||
|
with
|
||||||
|
int_monthly_aggregated_metrics_history_by_deal as (
|
||||||
|
select * from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }}
|
||||||
|
),
|
||||||
|
int_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}),
|
||||||
|
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 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
|
||||||
|
|
@ -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
|
||||||
|
|
@ -82,15 +82,6 @@
|
||||||
},
|
},
|
||||||
{
|
{
|
||||||
"order_by": 21,
|
"order_by": 21,
|
||||||
"metric": "First Time Booked Deals",
|
|
||||||
"value": "first_time_booked_deals",
|
|
||||||
"previous_year_value": "previous_year_first_time_booked_deals",
|
|
||||||
"relative_increment": "relative_increment_first_time_booked_deals",
|
|
||||||
"number_format": "integer",
|
|
||||||
"increment_sign_format": "positive",
|
|
||||||
},
|
|
||||||
{
|
|
||||||
"order_by": 22,
|
|
||||||
"metric": "Deals Booked in Month",
|
"metric": "Deals Booked in Month",
|
||||||
"value": "deals_booked_in_month",
|
"value": "deals_booked_in_month",
|
||||||
"previous_year_value": "previous_year_deals_booked_in_month",
|
"previous_year_value": "previous_year_deals_booked_in_month",
|
||||||
|
|
@ -99,7 +90,7 @@
|
||||||
"increment_sign_format": "positive",
|
"increment_sign_format": "positive",
|
||||||
},
|
},
|
||||||
{
|
{
|
||||||
"order_by": 23,
|
"order_by": 22,
|
||||||
"metric": "Deals Booked in 6 Months",
|
"metric": "Deals Booked in 6 Months",
|
||||||
"value": "deals_booked_in_6_months",
|
"value": "deals_booked_in_6_months",
|
||||||
"previous_year_value": "previous_year_deals_booked_in_6_months",
|
"previous_year_value": "previous_year_deals_booked_in_6_months",
|
||||||
|
|
@ -108,7 +99,7 @@
|
||||||
"increment_sign_format": "positive",
|
"increment_sign_format": "positive",
|
||||||
},
|
},
|
||||||
{
|
{
|
||||||
"order_by": 24,
|
"order_by": 23,
|
||||||
"metric": "Deals Booked in 12 Months",
|
"metric": "Deals Booked in 12 Months",
|
||||||
"value": "deals_booked_in_12_months",
|
"value": "deals_booked_in_12_months",
|
||||||
"previous_year_value": "previous_year_deals_booked_in_12_months",
|
"previous_year_value": "previous_year_deals_booked_in_12_months",
|
||||||
|
|
@ -117,7 +108,7 @@
|
||||||
"increment_sign_format": "positive",
|
"increment_sign_format": "positive",
|
||||||
},
|
},
|
||||||
{
|
{
|
||||||
"order_by": 25,
|
"order_by": 24,
|
||||||
"metric": "Churning Deals",
|
"metric": "Churning Deals",
|
||||||
"value": "churning_deals",
|
"value": "churning_deals",
|
||||||
"previous_year_value": "previous_year_churning_deals",
|
"previous_year_value": "previous_year_churning_deals",
|
||||||
|
|
@ -307,7 +298,16 @@
|
||||||
},
|
},
|
||||||
{
|
{
|
||||||
"order_by": 203,
|
"order_by": 203,
|
||||||
"metric": "Expected Onboarding MRR per New Account",
|
"metric": "Expected Onboarding MRR per New Deal",
|
||||||
|
"value": "expected_mrr_per_deal",
|
||||||
|
"previous_year_value": "previous_year_expected_mrr_per_deal",
|
||||||
|
"relative_increment": "relative_increment_expected_mrr_per_deal",
|
||||||
|
"number_format": "currency_gbp",
|
||||||
|
"increment_sign_format": "positive",
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"order_by": 204,
|
||||||
|
"metric": "Expected Onboarding MRR",
|
||||||
"value": "expected_mrr",
|
"value": "expected_mrr",
|
||||||
"previous_year_value": "previous_year_expected_mrr",
|
"previous_year_value": "previous_year_expected_mrr",
|
||||||
"relative_increment": "relative_increment_expected_mrr",
|
"relative_increment": "relative_increment_expected_mrr",
|
||||||
|
|
|
||||||
|
|
@ -171,32 +171,11 @@ with
|
||||||
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
||||||
and dimension_value <> 'UNSET'
|
and dimension_value <> 'UNSET'
|
||||||
),
|
),
|
||||||
int_monthly_onboarding_mrr_metrics as (
|
int_monthly_onboarding_mrr_per_deal as (
|
||||||
select
|
select * from {{ ref("int_monthly_onboarding_mrr_per_deal") }}
|
||||||
date,
|
),
|
||||||
'by_number_of_listings' as dimension,
|
int_mtd_agg_onboarding_mrr_revenue as (
|
||||||
hubspot_listing_segmentation as dimension_value,
|
select * from {{ ref("int_mtd_agg_onboarding_mrr_revenue") }}
|
||||||
expected_mrr
|
|
||||||
from {{ ref("int_monthly_onboarding_mrr_metrics") }}
|
|
||||||
where
|
|
||||||
main_billing_country_iso_3 = 'global'
|
|
||||||
and hubspot_listing_segmentation <> 'global'
|
|
||||||
union all
|
|
||||||
select
|
|
||||||
date,
|
|
||||||
'by_billing_country' as dimension,
|
|
||||||
main_billing_country_iso_3 as dimension_value,
|
|
||||||
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, expected_mrr
|
|
||||||
from {{ ref("int_monthly_onboarding_mrr_metrics") }}
|
|
||||||
where
|
|
||||||
hubspot_listing_segmentation = 'global'
|
|
||||||
and main_billing_country_iso_3 = 'global'
|
|
||||||
),
|
),
|
||||||
|
|
||||||
plain_kpi_combination as (
|
plain_kpi_combination as (
|
||||||
|
|
@ -241,7 +220,6 @@ with
|
||||||
-- DEALS --
|
-- DEALS --
|
||||||
deals.new_deals,
|
deals.new_deals,
|
||||||
deals.never_booked_deals,
|
deals.never_booked_deals,
|
||||||
deals.first_time_booked_deals,
|
|
||||||
deals.active_deals,
|
deals.active_deals,
|
||||||
deals.churning_deals,
|
deals.churning_deals,
|
||||||
deals.inactive_deals,
|
deals.inactive_deals,
|
||||||
|
|
@ -386,7 +364,8 @@ with
|
||||||
)",
|
)",
|
||||||
-1,
|
-1,
|
||||||
1
|
1
|
||||||
)}} as revenue_retained_ratio,
|
)
|
||||||
|
}} as revenue_retained_ratio,
|
||||||
|
|
||||||
-- INCOME RETAINED POST RESOLUTIONS--
|
-- INCOME RETAINED POST RESOLUTIONS--
|
||||||
nullif(
|
nullif(
|
||||||
|
|
@ -418,7 +397,8 @@ with
|
||||||
}} as revenue_retained_post_resolutions_ratio,
|
}} as revenue_retained_post_resolutions_ratio,
|
||||||
|
|
||||||
-- ONBOARDING MRR METRIC --
|
-- ONBOARDING MRR METRIC --
|
||||||
onboarding_mrr.expected_mrr as expected_mrr
|
onboarding_mrr.expected_mrr_per_deal,
|
||||||
|
onboarding_mrr_revenue.expected_mrr
|
||||||
|
|
||||||
from int_kpis__agg_dates_main_kpis d
|
from int_kpis__agg_dates_main_kpis d
|
||||||
left join
|
left join
|
||||||
|
|
@ -492,11 +472,17 @@ with
|
||||||
and d.dimension = churn.dimension
|
and d.dimension = churn.dimension
|
||||||
and d.dimension_value = churn.dimension_value
|
and d.dimension_value = churn.dimension_value
|
||||||
left join
|
left join
|
||||||
int_monthly_onboarding_mrr_metrics onboarding_mrr
|
int_monthly_onboarding_mrr_per_deal onboarding_mrr
|
||||||
on d.date = onboarding_mrr.date
|
on d.date = onboarding_mrr.date
|
||||||
and d.dimension = onboarding_mrr.dimension
|
and d.dimension = onboarding_mrr.dimension
|
||||||
and d.dimension_value = onboarding_mrr.dimension_value
|
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
|
select
|
||||||
current.year,
|
current.year,
|
||||||
current.month,
|
current.month,
|
||||||
|
|
@ -529,7 +515,6 @@ select
|
||||||
-- DEALS --
|
-- DEALS --
|
||||||
{{ calculate_safe_relative_increment("new_deals") }},
|
{{ calculate_safe_relative_increment("new_deals") }},
|
||||||
{{ calculate_safe_relative_increment("never_booked_deals") }},
|
{{ calculate_safe_relative_increment("never_booked_deals") }},
|
||||||
{{ calculate_safe_relative_increment("first_time_booked_deals") }},
|
|
||||||
{{ calculate_safe_relative_increment("active_deals") }},
|
{{ calculate_safe_relative_increment("active_deals") }},
|
||||||
{{ calculate_safe_relative_increment("churning_deals") }},
|
{{ calculate_safe_relative_increment("churning_deals") }},
|
||||||
{{ calculate_safe_relative_increment("inactive_deals") }},
|
{{ calculate_safe_relative_increment("inactive_deals") }},
|
||||||
|
|
@ -636,6 +621,7 @@ select
|
||||||
{{ calculate_safe_relative_increment("revenue_retained_post_resolutions_ratio") }},
|
{{ calculate_safe_relative_increment("revenue_retained_post_resolutions_ratio") }},
|
||||||
|
|
||||||
-- ONBOARDING MRR METRIC --
|
-- ONBOARDING MRR METRIC --
|
||||||
|
{{ calculate_safe_relative_increment("expected_mrr_per_deal") }},
|
||||||
{{ calculate_safe_relative_increment("expected_mrr") }}
|
{{ calculate_safe_relative_increment("expected_mrr") }}
|
||||||
|
|
||||||
from plain_kpi_combination current
|
from plain_kpi_combination current
|
||||||
|
|
|
||||||
|
|
@ -1707,7 +1707,7 @@ models:
|
||||||
data_type: boolean
|
data_type: boolean
|
||||||
description: "Flag to indicate if the deal is in Xero."
|
description: "Flag to indicate if the deal is in Xero."
|
||||||
|
|
||||||
- name: int_monthly_onboarding_mrr_metrics
|
- name: int_monthly_onboarding_mrr_per_deal
|
||||||
description: |
|
description: |
|
||||||
"This table provides data on the Onboarding Monthly Recurring Revenue (MRR).
|
"This table provides data on the Onboarding Monthly Recurring Revenue (MRR).
|
||||||
The Onboarding MRR is an estimate of the expected monthly revenue generated by
|
The Onboarding MRR is an estimate of the expected monthly revenue generated by
|
||||||
|
|
@ -1719,63 +1719,85 @@ models:
|
||||||
- dbt_utils.unique_combination_of_columns:
|
- dbt_utils.unique_combination_of_columns:
|
||||||
combination_of_columns:
|
combination_of_columns:
|
||||||
- date
|
- date
|
||||||
- main_billing_country_iso_3
|
- dimension
|
||||||
- hubspot_listing_segmentation
|
- dimension_value
|
||||||
|
|
||||||
columns:
|
columns:
|
||||||
- name: date
|
- name: date
|
||||||
data_type: date
|
data_type: date
|
||||||
description: |
|
description: The date for the month-to-date metrics.
|
||||||
"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:
|
data_tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
- name: hubspot_listing_segmentation
|
- name: dimension
|
||||||
data_type: text
|
data_type: string
|
||||||
description: |
|
description: The dimension or granularity of the metrics.
|
||||||
"Segmentation based on the number of properties specified by each deal
|
|
||||||
in HubSpot."
|
|
||||||
data_tests:
|
data_tests:
|
||||||
- not_null
|
|
||||||
- accepted_values:
|
- accepted_values:
|
||||||
values:
|
values:
|
||||||
- "01-05"
|
- global
|
||||||
- "06-20"
|
- by_number_of_listings
|
||||||
- "21-60"
|
- by_billing_country
|
||||||
- "61+"
|
|
||||||
- "global"
|
|
||||||
|
|
||||||
- name: total_revenue_in_gbp
|
- name: dimension_value
|
||||||
data_type: numeric
|
data_type: string
|
||||||
description: |
|
description: The value or segment available for the selected dimension.
|
||||||
"Total revenue accumulated by all active accounts over the last 12 months."
|
|
||||||
data_tests:
|
data_tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
- name: total_active_months
|
- name: expected_mrr_per_deal
|
||||||
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
|
data_type: numeric
|
||||||
description: |
|
description: |
|
||||||
"Expected MRR for each new deal."
|
"Expected MRR for each new deal."
|
||||||
data_tests:
|
data_tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: int_mtd_agg_onboarding_mrr_revenue
|
||||||
|
description: |
|
||||||
|
This model contains the month-to-date aggregated metrics for onboarding MRR.
|
||||||
|
It includes the total expected MRR revenue for the month, aggregated by
|
||||||
|
dimension for 'global' and 'by_number_of_listings' only.
|
||||||
|
- The 'by_number_of_listings' dimension is calculated by multiplying the
|
||||||
|
expected MRR per deal by the number of new deals in that segment.
|
||||||
|
- The 'global' dimension represents the sum of all expected MRRs across
|
||||||
|
all segments.
|
||||||
|
|
||||||
|
data_tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- date
|
||||||
|
- dimension
|
||||||
|
- dimension_value
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: date
|
||||||
|
data_type: date
|
||||||
|
description: The date for the month-to-date metrics.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: dimension
|
||||||
|
data_type: string
|
||||||
|
description: The dimension or granularity of the metrics.
|
||||||
|
data_tests:
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- global
|
||||||
|
- by_number_of_listings
|
||||||
|
|
||||||
|
- name: dimension_value
|
||||||
|
data_type: string
|
||||||
|
description: The value or segment available for the selected dimension.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: number_of_new_deals
|
||||||
|
data_type: numeric
|
||||||
|
description: Number of new deals in the month.
|
||||||
|
|
||||||
|
- name: expected_mrr
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
Total expected Onboarding MRR.
|
||||||
|
This is calculated by multiplying the expected MRR per deal by the number of new deals.
|
||||||
|
For the "global" dimension, it is the sum of all expected MRRs across segments.
|
||||||
|
|
|
||||||
|
|
@ -28,7 +28,7 @@ with
|
||||||
booked_days_per_deal as (
|
booked_days_per_deal as (
|
||||||
select
|
select
|
||||||
icuh.id_deal,
|
icuh.id_deal,
|
||||||
icb.created_date_utc,
|
icb.created_date_utc as created_date_utc,
|
||||||
lag(icb.created_date_utc, 1) over (
|
lag(icb.created_date_utc, 1) over (
|
||||||
partition by icuh.id_deal order by icb.created_date_utc asc
|
partition by icuh.id_deal order by icb.created_date_utc asc
|
||||||
) as previous_booked_date
|
) as previous_booked_date
|
||||||
|
|
@ -37,6 +37,18 @@ with
|
||||||
where icuh.id_deal is not null
|
where icuh.id_deal is not null
|
||||||
group by icuh.id_deal, icb.created_date_utc
|
group by icuh.id_deal, icb.created_date_utc
|
||||||
),
|
),
|
||||||
|
deals as (
|
||||||
|
select
|
||||||
|
coalesce(hd.id_deal, h.id_deal) as id_deal,
|
||||||
|
min(coalesce(hd.live_date_utc, h.created_date_utc)) as created_date_utc
|
||||||
|
from int_hubspot__deal hd
|
||||||
|
full outer join
|
||||||
|
int_core__user_host h
|
||||||
|
on hd.id_deal = h.id_deal
|
||||||
|
where hd.id_deal is not null
|
||||||
|
and h.id_deal is not null
|
||||||
|
group by 1
|
||||||
|
),
|
||||||
deal_historic_booking_dates as (
|
deal_historic_booking_dates as (
|
||||||
select
|
select
|
||||||
d.date,
|
d.date,
|
||||||
|
|
@ -46,7 +58,7 @@ with
|
||||||
max(b.created_date_utc) as last_time_booked_date_utc,
|
max(b.created_date_utc) as last_time_booked_date_utc,
|
||||||
max(b.previous_booked_date) as second_to_last_time_booked_date_utc
|
max(b.previous_booked_date) as second_to_last_time_booked_date_utc
|
||||||
from int_kpis__dimension_dates d
|
from int_kpis__dimension_dates d
|
||||||
inner join int_core__user_host h on d.date >= h.created_date_utc
|
inner join deals h on d.date >= h.created_date_utc
|
||||||
left join
|
left join
|
||||||
booked_days_per_deal b
|
booked_days_per_deal b
|
||||||
on h.id_deal = b.id_deal
|
on h.id_deal = b.id_deal
|
||||||
|
|
@ -144,9 +156,7 @@ select
|
||||||
case
|
case
|
||||||
-- 01-New: The deal has been created this month.
|
-- 01-New: The deal has been created this month.
|
||||||
-- Additionally, the deal has not been offboarded in hubspot.
|
-- Additionally, the deal has not been offboarded in hubspot.
|
||||||
when
|
when deal_was_created_this_month and not deal_has_been_offboarded
|
||||||
deal_was_created_this_month
|
|
||||||
and not deal_has_been_offboarded
|
|
||||||
then '01-New'
|
then '01-New'
|
||||||
-- 02-Never Booked: The deal has been created before this month and has not
|
-- 02-Never Booked: The deal has been created before this month and has not
|
||||||
-- had any booking. Additionally, the deal has not been offboarded in hubspot.
|
-- had any booking. Additionally, the deal has not been offboarded in hubspot.
|
||||||
|
|
|
||||||
|
|
@ -14,9 +14,11 @@ select
|
||||||
coalesce(
|
coalesce(
|
||||||
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||||
) as main_billing_country_iso_3_per_deal,
|
) as main_billing_country_iso_3_per_deal,
|
||||||
coalesce(
|
case
|
||||||
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
|
when ldl.deal_lifecycle_state = '01-New'
|
||||||
) as active_accommodations_per_deal_segmentation,
|
then coalesce(dd.hubspot_listing_segmentation, 'UNSET')
|
||||||
|
else coalesce(icmas.active_accommodations_per_deal_segmentation, 'UNSET')
|
||||||
|
end as active_accommodations_per_deal_segmentation,
|
||||||
-- Metrics --
|
-- Metrics --
|
||||||
count(
|
count(
|
||||||
distinct case
|
distinct case
|
||||||
|
|
@ -66,6 +68,7 @@ select
|
||||||
) as deals_booked_in_12_months
|
) as deals_booked_in_12_months
|
||||||
from {{ ref("int_kpis__lifecycle_daily_deal") }} as ldl
|
from {{ ref("int_kpis__lifecycle_daily_deal") }} as ldl
|
||||||
left join {{ ref("int_core__deal") }} as icd on ldl.id_deal = icd.id_deal
|
left join {{ ref("int_core__deal") }} as icd on ldl.id_deal = icd.id_deal
|
||||||
|
left join {{ ref("int_kpis__dimension_deals") }} as dd on ldl.id_deal = dd.id_deal
|
||||||
left join
|
left join
|
||||||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||||
on ldl.id_deal = icmas.id_deal
|
on ldl.id_deal = icmas.id_deal
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue