Merged PR 4931: KPIs Refactor Stage 3 - Remove previous Churn models
# Description Removes the models: * int_monthly_12m_window_contribution_by_deal * int_monthly_churn_metrics as well as their entries in the schema files. Project compiles and KPIs run works. This closes stage 3 of the refactor. # Checklist - [ ] The edited models and dependants run properly with production data. - [ ] The edited models are sufficiently documented. - [ ] 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. Remove previous Churn models Related work items: #28948
This commit is contained in:
parent
4b9babf6b4
commit
63aebf4220
3 changed files with 0 additions and 427 deletions
|
|
@ -1,112 +0,0 @@
|
||||||
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
|
||||||
with
|
|
||||||
int_monthly_aggregated_metrics_history_by_deal as (
|
|
||||||
select * from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }}
|
|
||||||
),
|
|
||||||
aggregated_metrics_by_deal_over_12_months as (
|
|
||||||
select
|
|
||||||
am.date,
|
|
||||||
am.id_deal,
|
|
||||||
am.deal_lifecycle_state,
|
|
||||||
1.0 * count(*) over (
|
|
||||||
partition by am.id_deal
|
|
||||||
order by am.date
|
|
||||||
rows between 12 preceding and 1 preceding
|
|
||||||
) as preceding_months_count_by_deal,
|
|
||||||
1.0 * sum(am.total_revenue_in_gbp) over (
|
|
||||||
partition by am.id_deal
|
|
||||||
order by am.date
|
|
||||||
rows between 12 preceding and 1 preceding
|
|
||||||
) as sum_total_revenue_preceding_12_months,
|
|
||||||
1.0 * sum(am.created_bookings) over (
|
|
||||||
partition by am.id_deal
|
|
||||||
order by am.date
|
|
||||||
rows between 12 preceding and 1 preceding
|
|
||||||
) as sum_created_bookings_preceding_12_months,
|
|
||||||
1.0 * sum(am.listings_booked_in_month) over (
|
|
||||||
partition by am.id_deal
|
|
||||||
order by am.date
|
|
||||||
rows between 12 preceding and 1 preceding
|
|
||||||
) as sum_listings_booked_in_month_preceding_12_months
|
|
||||||
from int_monthly_aggregated_metrics_history_by_deal am
|
|
||||||
),
|
|
||||||
global_computation_over_12_months as (
|
|
||||||
select
|
|
||||||
ambd.id_deal,
|
|
||||||
ambd.date,
|
|
||||||
ambd.deal_lifecycle_state,
|
|
||||||
|
|
||||||
-- Amount of active months per deal used in the computation
|
|
||||||
ambd.preceding_months_count_by_deal,
|
|
||||||
case
|
|
||||||
when ambd.preceding_months_count_by_deal < 12 then true else false
|
|
||||||
end as has_deal_been_created_less_than_12_months_ago,
|
|
||||||
|
|
||||||
-- AVERAGE APPROACH --
|
|
||||||
-- 12 months window sum of metric divided by amount of active months per
|
|
||||||
-- deal
|
|
||||||
ambd.sum_total_revenue_preceding_12_months
|
|
||||||
/ ambd.preceding_months_count_by_deal
|
|
||||||
as avg_total_revenue_preceding_12_months,
|
|
||||||
ambd.sum_created_bookings_preceding_12_months
|
|
||||||
/ ambd.preceding_months_count_by_deal
|
|
||||||
as avg_created_bookings_preceding_12_months,
|
|
||||||
ambd.sum_listings_booked_in_month_preceding_12_months
|
|
||||||
/ ambd.preceding_months_count_by_deal
|
|
||||||
as avg_listings_booked_in_month_preceding_12_months,
|
|
||||||
|
|
||||||
-- Global amounts by sum of the 12 months window sum of metric on a given
|
|
||||||
-- date
|
|
||||||
sum(
|
|
||||||
ambd.sum_total_revenue_preceding_12_months
|
|
||||||
/ ambd.preceding_months_count_by_deal
|
|
||||||
) over (partition by ambd.date)
|
|
||||||
as avg_global_total_revenue_preceding_12_months,
|
|
||||||
sum(
|
|
||||||
ambd.sum_created_bookings_preceding_12_months
|
|
||||||
/ ambd.preceding_months_count_by_deal
|
|
||||||
) over (partition by ambd.date)
|
|
||||||
as avg_global_created_bookings_preceding_12_months,
|
|
||||||
sum(
|
|
||||||
ambd.sum_listings_booked_in_month_preceding_12_months
|
|
||||||
/ ambd.preceding_months_count_by_deal
|
|
||||||
) over (partition by ambd.date)
|
|
||||||
as avg_global_listings_booked_in_month_preceding_12_months
|
|
||||||
|
|
||||||
from aggregated_metrics_by_deal_over_12_months ambd
|
|
||||||
)
|
|
||||||
select
|
|
||||||
id_deal,
|
|
||||||
date,
|
|
||||||
deal_lifecycle_state,
|
|
||||||
|
|
||||||
-- Amount of active months per deal used in the computation
|
|
||||||
preceding_months_count_by_deal,
|
|
||||||
|
|
||||||
-- Revenue pre-computation metrics for further aggregation downstream
|
|
||||||
coalesce(
|
|
||||||
avg_total_revenue_preceding_12_months, 0
|
|
||||||
) as avg_total_revenue_preceding_12_months,
|
|
||||||
coalesce(
|
|
||||||
avg_global_total_revenue_preceding_12_months, 0
|
|
||||||
) as avg_global_total_revenue_preceding_12_months,
|
|
||||||
|
|
||||||
-- AVERAGE APPROACH --
|
|
||||||
-- 12 months window sum of metric divided by amount of active months per deal
|
|
||||||
coalesce(
|
|
||||||
avg_total_revenue_preceding_12_months
|
|
||||||
/ nullif(avg_global_total_revenue_preceding_12_months, 0),
|
|
||||||
0
|
|
||||||
) as total_revenue_12m_average_contribution,
|
|
||||||
coalesce(
|
|
||||||
avg_created_bookings_preceding_12_months
|
|
||||||
/ nullif(avg_global_created_bookings_preceding_12_months, 0),
|
|
||||||
0
|
|
||||||
) as created_bookings_12m_average_contribution,
|
|
||||||
coalesce(
|
|
||||||
avg_listings_booked_in_month_preceding_12_months
|
|
||||||
/ nullif(avg_global_listings_booked_in_month_preceding_12_months, 0),
|
|
||||||
0
|
|
||||||
) as listings_booked_in_month_12m_average_contribution
|
|
||||||
|
|
||||||
from global_computation_over_12_months
|
|
||||||
|
|
@ -1,111 +0,0 @@
|
||||||
{% set dimensions = get_kpi_dimensions_per_model("CHURN_RATES") %}
|
|
||||||
{% set churn_lifecycle_states = "('05-Churning')" %}
|
|
||||||
|
|
||||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
|
||||||
with
|
|
||||||
int_monthly_12m_window_contribution_by_deal as (
|
|
||||||
select * from {{ ref("int_monthly_12m_window_contribution_by_deal") }}
|
|
||||||
),
|
|
||||||
int_kpis__agg_dates_main_kpis as (
|
|
||||||
select *
|
|
||||||
from {{ ref("int_kpis__agg_dates_main_kpis") }}
|
|
||||||
where
|
|
||||||
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
||||||
and dimension_value <> 'UNSET'
|
|
||||||
),
|
|
||||||
int_kpis__dimension_daily_accommodation as (
|
|
||||||
select * from {{ ref("int_kpis__dimension_daily_accommodation") }}
|
|
||||||
),
|
|
||||||
int_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}),
|
|
||||||
churn_metrics_per_date as (
|
|
||||||
{% for dimension in dimensions %}
|
|
||||||
select
|
|
||||||
m12wc.date,
|
|
||||||
{{ dimension.dimension }} as dimension,
|
|
||||||
{{ dimension.dimension_value }} as dimension_value,
|
|
||||||
|
|
||||||
-- Revenue Churn 12m rolling window (absolute figures) --
|
|
||||||
sum(
|
|
||||||
case
|
|
||||||
when m12wc.deal_lifecycle_state in {{ churn_lifecycle_states }}
|
|
||||||
then m12wc.avg_total_revenue_preceding_12_months
|
|
||||||
else 0
|
|
||||||
end
|
|
||||||
) as total_revenue_churn_preceding_12_months,
|
|
||||||
|
|
||||||
-- Global Revenue 12m rolling window --
|
|
||||||
max(
|
|
||||||
m12wc.avg_global_total_revenue_preceding_12_months
|
|
||||||
) as total_revenue_global_preceding_12_months,
|
|
||||||
|
|
||||||
-- Churn Rates --
|
|
||||||
sum(
|
|
||||||
case
|
|
||||||
when m12wc.deal_lifecycle_state in {{ churn_lifecycle_states }}
|
|
||||||
then m12wc.total_revenue_12m_average_contribution
|
|
||||||
else 0
|
|
||||||
end
|
|
||||||
) as total_revenue_churn_average_contribution,
|
|
||||||
sum(
|
|
||||||
case
|
|
||||||
when m12wc.deal_lifecycle_state in {{ churn_lifecycle_states }}
|
|
||||||
then m12wc.created_bookings_12m_average_contribution
|
|
||||||
else 0
|
|
||||||
end
|
|
||||||
) as created_bookings_churn_average_contribution,
|
|
||||||
sum(
|
|
||||||
case
|
|
||||||
when m12wc.deal_lifecycle_state in {{ churn_lifecycle_states }}
|
|
||||||
then m12wc.listings_booked_in_month_12m_average_contribution
|
|
||||||
else 0
|
|
||||||
end
|
|
||||||
) as listings_booked_in_month_churn_average_contribution
|
|
||||||
from int_monthly_12m_window_contribution_by_deal m12wc
|
|
||||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
|
||||||
inner join
|
|
||||||
int_kpis__dimension_daily_accommodation dda
|
|
||||||
on m12wc.id_deal = dda.id_deal
|
|
||||||
and m12wc.date = dda.date
|
|
||||||
{% elif dimension.dimension == "'by_billing_country'" %}
|
|
||||||
inner join
|
|
||||||
int_kpis__dimension_deals ud
|
|
||||||
on m12wc.id_deal = ud.id_deal
|
|
||||||
and ud.main_billing_country_iso_3_per_deal is not null
|
|
||||||
{% endif %}
|
|
||||||
where deal_lifecycle_state is not null
|
|
||||||
group by 1, 2, 3
|
|
||||||
{% if not loop.last %}
|
|
||||||
union all
|
|
||||||
{% endif %}
|
|
||||||
{% endfor %}
|
|
||||||
)
|
|
||||||
-- Final aggregation of subqueries --
|
|
||||||
select
|
|
||||||
d.year,
|
|
||||||
d.month,
|
|
||||||
d.day,
|
|
||||||
d.date,
|
|
||||||
d.dimension,
|
|
||||||
d.dimension_value,
|
|
||||||
d.is_end_of_month,
|
|
||||||
d.is_current_month,
|
|
||||||
c.total_revenue_churn_preceding_12_months,
|
|
||||||
c.total_revenue_global_preceding_12_months,
|
|
||||||
cast(
|
|
||||||
c.total_revenue_churn_average_contribution as numeric(19, 6)
|
|
||||||
) as total_revenue_churn_average_contribution,
|
|
||||||
cast(
|
|
||||||
c.created_bookings_churn_average_contribution as numeric(19, 6)
|
|
||||||
) as created_bookings_churn_average_contribution,
|
|
||||||
cast(
|
|
||||||
c.listings_booked_in_month_churn_average_contribution as numeric(19, 6)
|
|
||||||
) as listings_booked_in_month_churn_average_contribution
|
|
||||||
from int_kpis__agg_dates_main_kpis d
|
|
||||||
left join
|
|
||||||
churn_metrics_per_date c
|
|
||||||
on c.date = d.date
|
|
||||||
and c.dimension = d.dimension
|
|
||||||
and c.dimension_value = d.dimension_value
|
|
||||||
-- Remove current month dates since data won't be available anyway. This is specific
|
|
||||||
-- for this churn metrics model
|
|
||||||
where d.is_current_month = false
|
|
||||||
|
|
@ -1106,210 +1106,6 @@ models:
|
||||||
- MAJOR GAIN
|
- MAJOR GAIN
|
||||||
- UNSET
|
- UNSET
|
||||||
|
|
||||||
- name: int_monthly_12m_window_contribution_by_deal
|
|
||||||
deprecation_date: 2025-04-08
|
|
||||||
description: |
|
|
||||||
The main goal of this model is to provide how much a deal
|
|
||||||
contributes to a given metric on the global amount over a
|
|
||||||
period of 12 months.
|
|
||||||
|
|
||||||
At the moment, this is only done for 3 metrics:
|
|
||||||
- total_revenue_in_gbp
|
|
||||||
- created_bookings
|
|
||||||
- listings_booked_in_month
|
|
||||||
|
|
||||||
The contribution is based on an Average approach:
|
|
||||||
Over a period of 12 months, sum the value of a given a metric
|
|
||||||
for each deal, and divide it by the amount of months we're considering
|
|
||||||
for that deal. Sum all the average amounts per deals to get a global.
|
|
||||||
Divide the avg per deal value vs. the sum of avgs global one.
|
|
||||||
The average approach "boosts" the contribution of those accounts
|
|
||||||
that have been active for less than 12 months.
|
|
||||||
|
|
||||||
data_tests:
|
|
||||||
- dbt_utils.unique_combination_of_columns:
|
|
||||||
combination_of_columns:
|
|
||||||
- date
|
|
||||||
- id_deal
|
|
||||||
|
|
||||||
columns:
|
|
||||||
- name: date
|
|
||||||
data_type: date
|
|
||||||
description: |
|
|
||||||
Date corresponding to the last day of the month.
|
|
||||||
Metrics are inclusive to this date. Together with id_deal, it
|
|
||||||
acts as the primary key of this model.
|
|
||||||
data_tests:
|
|
||||||
- not_null
|
|
||||||
|
|
||||||
- name: id_deal
|
|
||||||
data_type: string
|
|
||||||
description: |
|
|
||||||
Unique identifier of a Deal. Together with date, it acts as
|
|
||||||
the primary key of this model.
|
|
||||||
data_tests:
|
|
||||||
- not_null
|
|
||||||
|
|
||||||
- name: deal_lifecycle_state
|
|
||||||
data_type: string
|
|
||||||
description: |
|
|
||||||
Identifier of the lifecycle state of a given deal
|
|
||||||
in a given month.
|
|
||||||
|
|
||||||
- name: preceding_months_count_by_deal
|
|
||||||
data_type: integer
|
|
||||||
description: |
|
|
||||||
Number of months preceding to the one given by date
|
|
||||||
that are used for the historic metric retrieval for
|
|
||||||
a given deal. In essence it states the amount of
|
|
||||||
months a given deal has been active before a the month
|
|
||||||
given by date, capped at 12 months.
|
|
||||||
data_tests:
|
|
||||||
- dbt_expectations.expect_column_values_to_be_between:
|
|
||||||
min_value: 0
|
|
||||||
max_value: 12
|
|
||||||
strictly: false
|
|
||||||
|
|
||||||
- name: has_deal_been_created_less_than_12_months_ago
|
|
||||||
data_type: boolean
|
|
||||||
description: |
|
|
||||||
Flag to identify if a given deal has been created less
|
|
||||||
than 12 months ago (true) or not (false). It's based on the
|
|
||||||
preceding_months_count_by_deal, and will be true on the first
|
|
||||||
year of deal activity.
|
|
||||||
|
|
||||||
- name: total_revenue_12m_average_contribution
|
|
||||||
data_type: numeric
|
|
||||||
description: |
|
|
||||||
Share of the deal contribution on total revenue
|
|
||||||
vs. the global amount, on the preceding 12 months
|
|
||||||
with respect to date. It uses the average approach.
|
|
||||||
It can be negative.
|
|
||||||
data_tests:
|
|
||||||
- not_null
|
|
||||||
|
|
||||||
- name: created_bookings_12m_average_contribution
|
|
||||||
data_type: numeric
|
|
||||||
description: |
|
|
||||||
Share of the deal contribution on created bookings
|
|
||||||
vs. the global amount, on the preceding 12 months
|
|
||||||
with respect to date. It uses the average approach.
|
|
||||||
data_tests:
|
|
||||||
- not_null
|
|
||||||
- dbt_expectations.expect_column_values_to_be_between:
|
|
||||||
min_value: 0
|
|
||||||
max_value: 1
|
|
||||||
strictly: false
|
|
||||||
|
|
||||||
- name: listings_booked_in_month_12m_average_contribution
|
|
||||||
data_type: numeric
|
|
||||||
description: |
|
|
||||||
Share of the deal contribution on listings booked in month
|
|
||||||
vs. the global amount, on the preceding 12 months
|
|
||||||
with respect to date. It uses the average approach.
|
|
||||||
data_tests:
|
|
||||||
- not_null
|
|
||||||
- dbt_expectations.expect_column_values_to_be_between:
|
|
||||||
min_value: 0
|
|
||||||
max_value: 1
|
|
||||||
strictly: false
|
|
||||||
|
|
||||||
- name: avg_total_revenue_preceding_12_months
|
|
||||||
data_type: numeric
|
|
||||||
description: |
|
|
||||||
Total revenue in GBP generated by a single deal
|
|
||||||
in the 12 months period. This uses an average approach,
|
|
||||||
meaning that the revenue of that deal is divided by the
|
|
||||||
amount of months it has been active.
|
|
||||||
|
|
||||||
- name: avg_global_total_revenue_preceding_12_months
|
|
||||||
data_type: numeric
|
|
||||||
description: |
|
|
||||||
Total revenue in GBP generated by a all deals
|
|
||||||
in the 12 months period. This uses an average approach,
|
|
||||||
meaning that the revenue of each deal is divided by the
|
|
||||||
amount of months it has been active.
|
|
||||||
|
|
||||||
- name: int_monthly_churn_metrics
|
|
||||||
deprecation_date: 2025-04-08
|
|
||||||
description: |
|
|
||||||
This model is used for global KPIs.
|
|
||||||
|
|
||||||
It computes the churn contribution by dimension, dimension value
|
|
||||||
and date, in a monthly basis. This model is different from the
|
|
||||||
usual mtd ones since it strictly depends on the monthly computation
|
|
||||||
of metrics by deal, which is done in a monthly basis rather than mtd.
|
|
||||||
In essence, it means we won't have data for the current month.
|
|
||||||
|
|
||||||
This model retrieves the 12 month contribution to global metrics
|
|
||||||
by deal and aggregates it to dimension and dimension value for those
|
|
||||||
deals that are tagged as '05-Churning' in that month. Thus, it provides
|
|
||||||
a total of 3 churn related metrics, represented as ratios over the total:
|
|
||||||
- Total Revenue (in GBP)
|
|
||||||
- Created Bookings
|
|
||||||
- Listings Booked in Month
|
|
||||||
by using the Average contribution method. For further
|
|
||||||
information, please refer to the documentation of the model:
|
|
||||||
- int_monthly_12m_window_contribution_by_deal
|
|
||||||
|
|
||||||
Lastly, when checking data at any dimension distinct from Global, at the
|
|
||||||
moment these values represent the additive contribution of churn with respect
|
|
||||||
to the global amount. This means that, for instance, if we have 10% of churn
|
|
||||||
in a month, it can be divided by 9% USA and 1% GBR since 9%+1% = 10%.
|
|
||||||
|
|
||||||
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
|
|
||||||
- by_billing_country
|
|
||||||
|
|
||||||
- name: dimension_value
|
|
||||||
data_type: string
|
|
||||||
description: The value or segment available for the selected dimension.
|
|
||||||
data_tests:
|
|
||||||
- not_null
|
|
||||||
|
|
||||||
- name: total_revenue_churn_preceding_12_months
|
|
||||||
data_type: numeric
|
|
||||||
description: |
|
|
||||||
Total Revenue attributed to have churned considering the
|
|
||||||
revenue generated by the deals in the 12 months period.
|
|
||||||
|
|
||||||
- name: total_revenue_global_preceding_12_months
|
|
||||||
data_type: numeric
|
|
||||||
description: |
|
|
||||||
Total Revenue generated by all deals in the 12 months period.
|
|
||||||
|
|
||||||
- name: total_revenue_churn_average_contribution
|
|
||||||
data_type: numeric
|
|
||||||
description: Total Revenue churn rate (average approach).
|
|
||||||
|
|
||||||
- name: created_bookings_churn_average_contribution
|
|
||||||
data_type: numeric
|
|
||||||
description: Created Bookings churn rate (average approach).
|
|
||||||
|
|
||||||
- name: listings_booked_in_month_churn_average_contribution
|
|
||||||
data_type: numeric
|
|
||||||
description: Listings Booked in Month churn rate (average approach).
|
|
||||||
|
|
||||||
- name: int_edeposit_and_athena_verifications
|
- name: int_edeposit_and_athena_verifications
|
||||||
description:
|
description:
|
||||||
"This table holds records on verifications for Guesty and Edeposit bookings.
|
"This table holds records on verifications for Guesty and Edeposit bookings.
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue