Merged PR 2171: Adding Guest Journey metrics by deal id

Adding the 6 Guest Journey metrics by deal id by creating the model `int_core__monthly_guest_journey_history_by_deal`

The structure for the deal id detail follows yesterday's approach on bookings, namely `int_core__monthly_booking_history_by_deal`, but considering the metric computation of the guest journey, namely `int_core__mtd_guest_journey_metrics`.

It also adds the dbt tests ensuring that date and id_deal are not null and that the combination of both is unique.

Related work items: #17689
This commit is contained in:
Oriol Roqué Paniagua 2024-07-02 07:26:20 +00:00
parent 010135fb63
commit 1a4b6b4c14
2 changed files with 94 additions and 0 deletions

View file

@ -0,0 +1,71 @@
/*
This model provides monthly guest journey metrics for those hosts that have a deal assigned.
*/
{{ config(materialized="table", unique_key=["date","id_deal"]) }}
with
int_core__verification_requests as (select * from {{ ref("int_core__verification_requests") }}),
int_dates_by_deal as (select * from {{ ref("int_dates_by_deal") }}),
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
-- Created Guest Journeys by id_deal --
created_year_month as (
select
date_trunc('month', vr.created_date_utc)::date as first_day_month,
u.id_deal,
count(distinct vr.id_verification_request) as created_guest_journeys
from int_core__unified_user u
inner join int_core__verification_requests vr
on u.id_user = vr.id_user_host
where u.id_deal is not null
group by 1,2
),
-- Started Guest Journeys by id_deal --
started_year_month as (
select
date_trunc('month', vr.verification_estimated_started_date_utc)::date as first_day_month,
u.id_deal,
count(distinct vr.id_verification_request) as started_guest_journeys
from int_core__unified_user u
inner join int_core__verification_requests vr
on u.id_user = vr.id_user_host
where u.id_deal is not null
group by 1,2
),
-- Completed Guest Journeys by id_deal --
completed_year_month as (
select
date_trunc('month', vr.verification_estimated_completed_date_utc)::date as first_day_month,
u.id_deal,
count(distinct vr.id_verification_request) as completed_guest_journeys
from int_core__unified_user u
inner join int_core__verification_requests vr
on u.id_user = vr.id_user_host
where u.id_deal is not null
group by 1,2
)
-- Final aggregation of subqueries + rates computation --
select
d.year,
d.month,
d.day,
d.date,
d.id_deal,
cym.created_guest_journeys,
sym.started_guest_journeys,
coym.completed_guest_journeys,
cast(sym.started_guest_journeys as decimal)/cym.created_guest_journeys as start_rate_guest_journey,
cast(coym.completed_guest_journeys as decimal)/sym.started_guest_journeys as completion_rate_guest_journey,
1-cast(coym.completed_guest_journeys as decimal)/sym.started_guest_journeys as incompletion_rate_guest_journey
from int_dates_by_deal d
left join created_year_month cym
on d.first_day_month = cym.first_day_month
and d.id_deal = cym.id_deal
left join started_year_month sym
on d.first_day_month = sym.first_day_month
and d.id_deal = sym.id_deal
left join completed_year_month coym
on d.first_day_month = coym.first_day_month
and d.id_deal = coym.id_deal

View file

@ -167,6 +167,29 @@ models:
tests:
- not_null
- name: int_core__monthly_guest_journey_history_by_deal
description: |
This model contains the historic information regarding the guest journey for each deal id.
It's used for the business KPIs in the view by deal id. Data is aggregated at the last
day of the month, or up to yesterday if it's the current month.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- id_deal
columns:
- name: date
data_type: date
description: The last day of the month or yesterday for historic guest journey metrics.
tests:
- not_null
- name: id_deal
data_type: character varying
description: Id of the deal associated to the host.
tests:
- not_null
- name: int_core__mtd_booking_metrics
description: |