Merged PR 2534: Deal metrics per customer segmentation

# Description

Modifies `int_core__mtd_deal_metrics` to include the customer segmentation based on listings. `schema.yaml` is also affected including new fields and tests. Hardcoded `int_core__mtd_vs_previous_year_metrics` to avoid propagating this upwards and messing up with the data display.

Overall, follows a similar strategy as we did for Booking and Guest Journey metrics. For reference, [here's the previous PR on GJ](https://guardhog.visualstudio.com/Data/_git/data-dwh-dbt-project/pullrequest/2533).

# 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.
- [X] I have checked for DRY opportunities with other models and docs.
- [X] I've picked the right materialization for the affected models.

# Other

- [ ] Check if a full-refresh is required after this PR is merged.

Related work items: #19325
This commit is contained in:
Oriol Roqué Paniagua 2024-08-09 10:03:35 +00:00
parent 6a660aeac8
commit d323460d1a
3 changed files with 118 additions and 64 deletions

View file

@ -2,73 +2,98 @@
This model provides Month-To-Date (MTD) based on Deal metrics. This model provides Month-To-Date (MTD) based on Deal metrics.
*/ */
{{ config(materialized="table", unique_key="date") }}
{% set dimensions = get_kpi_dimensions() %}
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
with with
int_core__mtd_deal_lifecycle as ( int_core__mtd_deal_lifecycle as (
select * from {{ ref("int_core__mtd_deal_lifecycle") }} select * from {{ ref("int_core__mtd_deal_lifecycle") }}
), ),
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}), int_dates_mtd_by_dimension as (
select * from {{ ref("int_dates_mtd_by_dimension") }}
),
int_core__mtd_accommodation_segmentation as (
select * from {{ ref("int_core__mtd_accommodation_segmentation") }}
),
deals_metric_aggregation_per_date as ( deals_metric_aggregation_per_date as (
select {% for dimension in dimensions %}
al.date, select
count( al.date,
distinct case {{ dimension.dimension }} as dimension,
when al.deal_lifecycle_state = '01-New' then al.id_deal else null {{ dimension.dimension_value }} as dimension_value,
end count(
) as new_deals, distinct case
count( when al.deal_lifecycle_state = '01-New'
distinct case then al.id_deal
when al.deal_lifecycle_state = '02-Never Booked' else null
then al.id_deal end
else null ) as new_deals,
end count(
) as never_booked_deals, distinct case
count( when al.deal_lifecycle_state = '02-Never Booked'
distinct case then al.id_deal
when al.deal_lifecycle_state = '03-First Time Booked' else null
then al.id_deal end
else null ) as never_booked_deals,
end count(
) as first_time_booked_deals, distinct case
count( when al.deal_lifecycle_state = '03-First Time Booked'
distinct case then al.id_deal
when al.deal_lifecycle_state = '04-Active' then al.id_deal else null else null
end end
) as active_deals, ) as first_time_booked_deals,
count( count(
distinct case distinct case
when al.deal_lifecycle_state = '05-Churning' when al.deal_lifecycle_state = '04-Active'
then al.id_deal then al.id_deal
else null else null
end end
) as churning_deals, ) as active_deals,
count( count(
distinct case distinct case
when al.deal_lifecycle_state = '06-Inactive' when al.deal_lifecycle_state = '05-Churning'
then al.id_deal then al.id_deal
else null else null
end end
) as inactive_deals, ) as churning_deals,
count( count(
distinct case distinct case
when al.deal_lifecycle_state = '07-Reactivated' when al.deal_lifecycle_state = '06-Inactive'
then al.id_deal then al.id_deal
else null else null
end end
) as reactivated_deals, ) as inactive_deals,
sum( count(
case when has_been_booked_within_current_month then 1 else 0 end distinct case
) as deals_booked_in_month, when al.deal_lifecycle_state = '07-Reactivated'
sum( then al.id_deal
case when has_been_booked_within_last_6_months then 1 else 0 end else null
) as deals_booked_in_6_months, end
sum( ) as reactivated_deals,
case when has_been_booked_within_last_12_months then 1 else 0 end sum(
) as deals_booked_in_12_months case when has_been_booked_within_current_month then 1 else 0 end
) as deals_booked_in_month,
from int_core__mtd_deal_lifecycle al sum(
group by al.date case when has_been_booked_within_last_6_months then 1 else 0 end
) as deals_booked_in_6_months,
sum(
case when has_been_booked_within_last_12_months then 1 else 0 end
) as deals_booked_in_12_months
from int_core__mtd_deal_lifecycle al
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join
int_core__mtd_accommodation_segmentation mas
on al.id_deal = mas.id_deal
and al.date = mas.date
{% endif %}
group by 1, 2, 3
{% if not loop.last %}
union all
{% endif %}
{% endfor %}
) )
-- Final aggregation of subqueries -- -- Final aggregation of subqueries --
select select
@ -76,6 +101,8 @@ select
d.month, d.month,
d.day, d.day,
d.date, d.date,
d.dimension,
d.dimension_value,
d.is_end_of_month, d.is_end_of_month,
d.is_current_month, d.is_current_month,
nullif(l.new_deals, 0) as new_deals, nullif(l.new_deals, 0) as new_deals,
@ -88,5 +115,9 @@ select
nullif(l.deals_booked_in_month, 0) as deals_booked_in_month, nullif(l.deals_booked_in_month, 0) as deals_booked_in_month,
nullif(l.deals_booked_in_6_months, 0) as deals_booked_in_6_months, nullif(l.deals_booked_in_6_months, 0) as deals_booked_in_6_months,
nullif(l.deals_booked_in_12_months, 0) as deals_booked_in_12_months nullif(l.deals_booked_in_12_months, 0) as deals_booked_in_12_months
from int_dates_mtd d from int_dates_mtd_by_dimension d
left join deals_metric_aggregation_per_date l on l.date = d.date left join
deals_metric_aggregation_per_date l
on l.date = d.date
and l.dimension = d.dimension
and l.dimension_value = d.dimension_value

View file

@ -297,6 +297,13 @@ models:
It's used for the business KPIs. Data is aggregated at the last day of the month and in the It's used for the business KPIs. Data is aggregated at the last day of the month and in the
days necessary for the Month-to-Date computation of the current month. days necessary for the Month-to-Date computation of the current month.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- dimension
- dimension_value
columns: columns:
- name: date - name: date
data_type: date data_type: date
@ -317,7 +324,21 @@ models:
description: The date for the month-to-date deal-related metrics. description: The date for the month-to-date deal-related metrics.
tests: tests:
- not_null - not_null
- unique
- name: dimension
data_type: string
description: The dimension or granularity of the metrics.
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.
tests:
- not_null
- name: int_core__mtd_guest_payments_metrics - name: int_core__mtd_guest_payments_metrics
description: | description: |

View file

@ -19,6 +19,8 @@ with
), ),
int_core__mtd_deal_metrics as ( int_core__mtd_deal_metrics as (
select * from {{ ref("int_core__mtd_deal_metrics") }} select * from {{ ref("int_core__mtd_deal_metrics") }}
-- TEMPORAL: FORCING DIMENSION = GLOBAL TO AVOID BREAKING CHANGES IN PRODUCTION
where dimension = 'global'
), ),
int_core__mtd_guest_payments_metrics as ( int_core__mtd_guest_payments_metrics as (
select * from {{ ref("int_core__mtd_guest_payments_metrics") }} select * from {{ ref("int_core__mtd_guest_payments_metrics") }}