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:
parent
6116633590
commit
6a660aeac8
3 changed files with 145 additions and 39 deletions
|
|
@ -2,7 +2,11 @@
|
|||
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
|
||||
int_core__verification_requests as (
|
||||
select * from {{ ref("int_core__verification_requests") }}
|
||||
|
|
@ -10,7 +14,12 @@ with
|
|||
int_core__verification_payments as (
|
||||
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_by_dimension as (select * from {{ ref("int_dates_mtd_by_dimension") }}),
|
||||
|
||||
first_payment_per_verification_request as (
|
||||
select
|
||||
|
|
@ -24,47 +33,104 @@ with
|
|||
),
|
||||
-- Created Guest Journeys MTD --
|
||||
created_year_month as (
|
||||
select
|
||||
d.date, count(distinct vr.id_verification_request) as created_guest_journeys
|
||||
from int_dates_mtd d
|
||||
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
|
||||
group by 1
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(distinct vr.id_verification_request) as created_guest_journeys
|
||||
from int_dates_mtd d
|
||||
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_year_month as (
|
||||
select
|
||||
d.date, count(distinct vr.id_verification_request) as started_guest_journeys
|
||||
from int_dates_mtd d
|
||||
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
|
||||
group by 1
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(distinct vr.id_verification_request) as started_guest_journeys
|
||||
from int_dates_mtd d
|
||||
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_year_month as (
|
||||
select
|
||||
d.date,
|
||||
count(distinct vr.id_verification_request) as completed_guest_journeys
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
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
|
||||
group by 1
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(distinct vr.id_verification_request) as completed_guest_journeys
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
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_year_month as (
|
||||
select d.date, count(distinct p.id_verification_request) as paid_guest_journeys
|
||||
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
|
||||
group by 1
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(distinct p.id_verification_request) as paid_guest_journeys
|
||||
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 --
|
||||
select
|
||||
|
|
@ -72,6 +138,8 @@ select
|
|||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.dimension,
|
||||
d.dimension_value,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
cym.created_guest_journeys,
|
||||
|
|
@ -87,8 +155,23 @@ select
|
|||
/ sym.started_guest_journeys as incompletion_rate_guest_journey,
|
||||
cast(pym.paid_guest_journeys as decimal)
|
||||
/ coym.completed_guest_journeys as payment_rate_guest_journey
|
||||
from int_dates_mtd d
|
||||
left join created_year_month cym on d.date = cym.date
|
||||
left join started_year_month sym on d.date = sym.date
|
||||
left join completed_year_month coym on d.date = coym.date
|
||||
left join paid_year_month pym on d.date = pym.date
|
||||
from int_dates_mtd_by_dimension d
|
||||
left join
|
||||
created_year_month cym
|
||||
on cym.date = d.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
|
||||
|
|
|
|||
|
|
@ -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
|
||||
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:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: The date for the month-to-date guest journey-related metrics.
|
||||
tests:
|
||||
- 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
|
||||
description: |
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue