Merged PR 2533: Guest Journey metrics per customer segmentation

# Description

Modifies `int_core__mtd_guest_journey_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 metrics.

# 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 08:41:14 +00:00
parent 6116633590
commit 6a660aeac8
3 changed files with 145 additions and 39 deletions

View file

@ -2,7 +2,11 @@
This model provides Month-To-Date (MTD) based on Guest Journey metrics. This model provides Month-To-Date (MTD) based on Guest Journey 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__verification_requests as ( int_core__verification_requests as (
select * from {{ ref("int_core__verification_requests") }} select * from {{ ref("int_core__verification_requests") }}
@ -10,7 +14,12 @@ with
int_core__verification_payments as ( int_core__verification_payments as (
select * from {{ ref("int_core__verification_payments") }} select * from {{ ref("int_core__verification_payments") }}
), ),
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
int_core__mtd_accommodation_segmentation as (
select * from {{ ref("int_core__mtd_accommodation_segmentation") }}
),
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}), int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
int_dates_mtd_by_dimension as (select * from {{ ref("int_dates_mtd_by_dimension") }}),
first_payment_per_verification_request as ( first_payment_per_verification_request as (
select select
@ -24,47 +33,104 @@ with
), ),
-- Created Guest Journeys MTD -- -- Created Guest Journeys MTD --
created_year_month as ( created_year_month as (
select {% for dimension in dimensions %}
d.date, count(distinct vr.id_verification_request) as created_guest_journeys select
from int_dates_mtd d d.date,
inner join {{ dimension.dimension }} as dimension,
int_core__verification_requests vr {{ dimension.dimension_value }} as dimension_value,
on date_trunc('month', vr.created_date_utc)::date = d.first_day_month count(distinct vr.id_verification_request) as created_guest_journeys
and extract(day from vr.created_date_utc) <= d.day from int_dates_mtd d
group by 1 inner join
int_core__verification_requests vr
on date_trunc('month', vr.created_date_utc)::date = d.first_day_month
and extract(day from vr.created_date_utc) <= d.day
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join int_core__user_host u on vr.id_user_host = u.id_user_host
inner join int_core__mtd_accommodation_segmentation mas
on u.id_deal = mas.id_deal
and d.date = mas.date
{% endif %}
group by 1, 2, 3
{% if not loop.last %}
union all
{% endif %}
{% endfor %}
), ),
-- Started Guest Journeys MTD -- -- Started Guest Journeys MTD --
started_year_month as ( started_year_month as (
select {% for dimension in dimensions %}
d.date, count(distinct vr.id_verification_request) as started_guest_journeys select
from int_dates_mtd d d.date,
inner join {{ dimension.dimension }} as dimension,
int_core__verification_requests vr {{ dimension.dimension_value }} as dimension_value,
on date_trunc('month', vr.verification_estimated_started_date_utc)::date = d.first_day_month count(distinct vr.id_verification_request) as started_guest_journeys
and extract(day from vr.verification_estimated_started_date_utc) <= d.day from int_dates_mtd d
group by 1 inner join
int_core__verification_requests vr
on date_trunc('month', vr.verification_estimated_started_date_utc)::date = d.first_day_month
and extract(day from vr.verification_estimated_started_date_utc) <= d.day
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join int_core__user_host u on vr.id_user_host = u.id_user_host
inner join int_core__mtd_accommodation_segmentation mas
on u.id_deal = mas.id_deal
and d.date = mas.date
{% endif %}
group by 1, 2, 3
{% if not loop.last %}
union all
{% endif %}
{% endfor %}
), ),
-- Completed Guest Journeys MTD -- -- Completed Guest Journeys MTD --
completed_year_month as ( completed_year_month as (
select {% for dimension in dimensions %}
d.date, select
count(distinct vr.id_verification_request) as completed_guest_journeys d.date,
from int_dates_mtd d {{ dimension.dimension }} as dimension,
inner join {{ dimension.dimension_value }} as dimension_value,
int_core__verification_requests vr count(distinct vr.id_verification_request) as completed_guest_journeys
on date_trunc('month', vr.verification_estimated_completed_date_utc)::date = d.first_day_month from int_dates_mtd d
and extract(day from vr.verification_estimated_completed_date_utc) <= d.day inner join
group by 1 int_core__verification_requests vr
on date_trunc('month', vr.verification_estimated_completed_date_utc)::date = d.first_day_month
and extract(day from vr.verification_estimated_completed_date_utc) <= d.day
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join int_core__user_host u on vr.id_user_host = u.id_user_host
inner join int_core__mtd_accommodation_segmentation mas
on u.id_deal = mas.id_deal
and d.date = mas.date
{% endif %}
group by 1, 2, 3
{% if not loop.last %}
union all
{% endif %}
{% endfor %}
), ),
-- Paid Guest Journeys MTD -- -- Paid Guest Journeys MTD --
paid_year_month as ( paid_year_month as (
select d.date, count(distinct p.id_verification_request) as paid_guest_journeys {% for dimension in dimensions %}
from int_dates_mtd d select
inner join d.date,
first_payment_per_verification_request p {{ dimension.dimension }} as dimension,
on date_trunc('month', p.first_payment_paid_date_utc)::date = d.first_day_month {{ dimension.dimension_value }} as dimension_value,
and extract(day from p.first_payment_paid_date_utc) <= d.day count(distinct p.id_verification_request) as paid_guest_journeys
group by 1 from int_dates_mtd d
inner join
first_payment_per_verification_request p
on date_trunc('month', p.first_payment_paid_date_utc)::date = d.first_day_month
and extract(day from p.first_payment_paid_date_utc) <= d.day
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join int_core__verification_requests vr on vr.id_verification_request = p.id_verification_request
inner join int_core__user_host u on vr.id_user_host = u.id_user_host
inner join int_core__mtd_accommodation_segmentation mas
on u.id_deal = mas.id_deal
and d.date = mas.date
{% endif %}
group by 1, 2, 3
{% if not loop.last %}
union all
{% endif %}
{% endfor %}
) )
-- Final aggregation of subqueries + rates computation -- -- Final aggregation of subqueries + rates computation --
select select
@ -72,6 +138,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,
cym.created_guest_journeys, cym.created_guest_journeys,
@ -87,8 +155,23 @@ select
/ sym.started_guest_journeys as incompletion_rate_guest_journey, / sym.started_guest_journeys as incompletion_rate_guest_journey,
cast(pym.paid_guest_journeys as decimal) cast(pym.paid_guest_journeys as decimal)
/ coym.completed_guest_journeys as payment_rate_guest_journey / coym.completed_guest_journeys as payment_rate_guest_journey
from int_dates_mtd d from int_dates_mtd_by_dimension d
left join created_year_month cym on d.date = cym.date left join
left join started_year_month sym on d.date = sym.date created_year_month cym
left join completed_year_month coym on d.date = coym.date on cym.date = d.date
left join paid_year_month pym on d.date = pym.date and cym.dimension = d.dimension
and cym.dimension_value = d.dimension_value
left join
started_year_month sym
on d.date = sym.date
and d.dimension = sym.dimension
and d.dimension_value = sym.dimension_value
left join
completed_year_month coym
on d.date = coym.date
and d.dimension = coym.dimension
and d.dimension_value = coym.dimension_value
left join paid_year_month pym
on d.date = pym.date
and d.dimension = pym.dimension
and d.dimension_value = pym.dimension_value

View file

@ -262,13 +262,34 @@ 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
description: The date for the month-to-date guest journey-related metrics. description: The date for the month-to-date guest journey-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_accommodation_metrics - name: int_core__mtd_accommodation_metrics
description: | description: |

View file

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