Merged PR 2825: Propagates deal Name and Billing Country in int_monthly_aggregated_metrics_history_by_deal

# Description

Changes (only in intermediate):
* Applies sqlfmt in KPIs source models (for some of them it was already applied). Specifically, the 3 Core models ONLY contains formatting changes
![image.png](https://guardhog.visualstudio.com/4148d95f-4b6d-4205-bcff-e9c8e0d2ca65/_apis/git/repositories/54ac356f-aad7-46d2-b62c-e8c5b3bb8ebf/pullRequests/2825/attachments/image.png)

* Adds `main_deal_name` and `main_billing_country_iso_3_per_deal` in `int_monthly_aggregated_metrics_history_by_deal`

* Adds the 2 new fields in the schema entry of `int_monthly_aggregated_metrics_history_by_deal`, including the dbt test not null in the deal name.

# 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: #18911, #19083
This commit is contained in:
Oriol Roqué Paniagua 2024-09-12 12:04:04 +00:00
parent 72c966631e
commit c336081d3d
5 changed files with 161 additions and 134 deletions

View file

@ -2,87 +2,90 @@
This model provides monthly booking metrics for those hosts that have a deal assigned.
*/
{{ config(materialized="table", unique_key=["date","id_deal"]) }}
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
with
int_core__bookings as (select * from {{ ref("int_core__bookings") }}),
int_core__booking_charge_events as (select * from {{ ref("int_core__booking_charge_events")}}),
int_core__booking_charge_events as (
select * from {{ ref("int_core__booking_charge_events") }}
),
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 Bookings by id_deal --
created_year_month as (
select
date_trunc('month', b.created_date_utc)::date as first_day_month,
u.id_deal,
select
date_trunc('month', b.created_date_utc)::date as first_day_month,
u.id_deal,
count(distinct b.id_booking) as created_bookings
from int_core__unified_user u
inner join int_core__bookings b
on u.id_user = b.id_user_host
from int_core__unified_user u
inner join int_core__bookings b on u.id_user = b.id_user_host
where u.id_deal is not null
group by 1,2
group by 1, 2
),
-- Checkout Bookings by id_deal --
check_out_year_month as (
select
date_trunc('month', b.check_out_date_utc)::date as first_day_month,
u.id_deal,
select
date_trunc('month', b.check_out_date_utc)::date as first_day_month,
u.id_deal,
count(distinct b.id_booking) as check_out_bookings
from int_core__unified_user u
inner join int_core__bookings b
on u.id_user = b.id_user_host
from int_core__unified_user u
inner join int_core__bookings b on u.id_user = b.id_user_host
where u.id_deal is not null
group by 1,2
group by 1, 2
),
-- Cancelled Bookings by id_deal --
-- Cancellation date equivalent to the last time the cancelled booking was updated
cancelled_year_month as (
select
select
date_trunc('month', b.updated_date_utc)::date as first_day_month,
u.id_deal,
u.id_deal,
count(distinct b.id_booking) as cancelled_bookings
from int_core__unified_user u
inner join int_core__bookings b
on u.id_user = b.id_user_host
where u.id_deal is not null
from int_core__unified_user u
inner join int_core__bookings b on u.id_user = b.id_user_host
where
u.id_deal is not null
and upper(b.booking_state) = {{ var("cancelled_booking_state") }}
group by 1,2
group by 1, 2
),
-- Billable Bookings by id_deal --
billable_year_month as (
select
date_trunc('month', bce.booking_fee_charge_date_utc)::date as first_day_month,
u.id_deal,
count(distinct bce.id_booking) as billable_bookings
from int_core__unified_user u
inner join int_core__bookings b
on u.id_user = b.id_user_host
inner join int_core__booking_charge_events bce
on b.id_booking = bce.id_booking
where u.id_deal is not null
group by 1,2
)
-- Final aggregation of subqueries --
select
d.year,
d.month,
d.day,
d.date,
d.id_deal,
crym.created_bookings,
coym.check_out_bookings,
caym.cancelled_bookings,
biym.billable_bookings
from int_dates_by_deal d
left join created_year_month crym
on crym.first_day_month = d.first_day_month
and crym.id_deal = d.id_deal
left join check_out_year_month coym
on coym.first_day_month = d.first_day_month
and coym.id_deal = d.id_deal
left join cancelled_year_month caym
on caym.first_day_month = d.first_day_month
and caym.id_deal = d.id_deal
left join billable_year_month biym
on biym.first_day_month = d.first_day_month
and biym.id_deal = d.id_deal
date_trunc('month', bce.booking_fee_charge_date_utc)::date
as first_day_month,
u.id_deal,
count(distinct bce.id_booking) as billable_bookings
from int_core__unified_user u
inner join int_core__bookings b on u.id_user = b.id_user_host
inner join int_core__booking_charge_events bce on b.id_booking = bce.id_booking
where u.id_deal is not null
group by 1, 2
)
-- Final aggregation of subqueries --
select
d.year,
d.month,
d.day,
d.date,
d.id_deal,
crym.created_bookings,
coym.check_out_bookings,
caym.cancelled_bookings,
biym.billable_bookings
from int_dates_by_deal d
left join
created_year_month crym
on crym.first_day_month = d.first_day_month
and crym.id_deal = d.id_deal
left join
check_out_year_month coym
on coym.first_day_month = d.first_day_month
and coym.id_deal = d.id_deal
left join
cancelled_year_month caym
on caym.first_day_month = d.first_day_month
and caym.id_deal = d.id_deal
left join
billable_year_month biym
on biym.first_day_month = d.first_day_month
and biym.id_deal = d.id_deal

View file

@ -2,97 +2,111 @@
This model provides monthly guest journey metrics for those hosts that have a deal assigned.
*/
{{ config(materialized="table", unique_key=["date","id_deal"]) }}
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
with
int_core__verification_requests as (select * from {{ ref("int_core__verification_requests") }}),
int_core__verification_payments as (select * from {{ ref("int_core__verification_payments") }}),
int_core__verification_requests as (
select * from {{ ref("int_core__verification_requests") }}
),
int_core__verification_payments as (
select * from {{ ref("int_core__verification_payments") }}
),
int_dates_by_deal as (select * from {{ ref("int_dates_by_deal") }}),
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
first_payment_per_verification_request AS (
select vp.id_verification_request, min(vp.payment_paid_date_utc) as first_payment_paid_date_utc
from int_core__verification_payments vp
where upper(vp.payment_status) = {{ var("paid_payment_state")}}
first_payment_per_verification_request as (
select
vp.id_verification_request,
min(vp.payment_paid_date_utc) as first_payment_paid_date_utc
from int_core__verification_payments vp
where
upper(vp.payment_status) = {{ var("paid_payment_state") }}
and vp.id_verification_request is not null
group by 1
group by 1
),
-- 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,
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
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
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,
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
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
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,
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
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
group by 1, 2
),
-- Paid Guest Journeys MTD --
paid_year_month as (
select
select
date_trunc('month', p.first_payment_paid_date_utc)::date as first_day_month,
u.id_deal,
u.id_deal,
count(distinct vr.id_verification_request) as paid_guest_journeys
from int_core__unified_user u
inner join int_core__verification_requests vr
on u.id_user = vr.id_user_host
inner join first_payment_per_verification_request p
from int_core__unified_user u
inner join int_core__verification_requests vr on u.id_user = vr.id_user_host
inner join
first_payment_per_verification_request p
on vr.id_verification_request = p.id_verification_request
where u.id_deal is not null
group by 1,2
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,
pym.paid_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,
cast(pym.paid_guest_journeys as decimal)/coym.completed_guest_journeys as payment_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
left join paid_year_month pym
on d.first_day_month = pym.first_day_month
and d.id_deal = pym.id_deal
-- 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,
pym.paid_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,
cast(pym.paid_guest_journeys as decimal)
/ coym.completed_guest_journeys as payment_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
left join
paid_year_month pym
on d.first_day_month = pym.first_day_month
and d.id_deal = pym.id_deal

View file

@ -3,7 +3,7 @@ This model provides Month-To-Date (MTD) deal lifecycle based on booking metrics.
Assumes a host will have a deal being filled.
*/
{{ config(materialized="table", unique_key=["date","id_deal"]) }}
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
with
int_core__bookings as (select * from {{ ref("int_core__bookings") }}),
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
@ -33,7 +33,7 @@ with
booked_days_per_host b
on h.id_user = b.id_user_host
and d.date >= b.created_date_utc
where h.id_deal is not null
where h.id_deal is not null
group by d.date, h.id_deal
),
deal_historic_booking_features as (
@ -111,15 +111,11 @@ select
second_to_last_time_booked_date_utc,
case
-- 01-New: The deal has been created this month and has not had any booking
when
not deal_has_at_least_one_booking
and deal_was_created_this_month
when not deal_has_at_least_one_booking and deal_was_created_this_month
then '01-New'
-- 02-Never Booked: The deal has been created before this month and has not
-- had any booking
when
not deal_has_at_least_one_booking
and not deal_was_created_this_month
when not deal_has_at_least_one_booking and not deal_was_created_this_month
then '02-Never Booked'
-- 03-First Time Booked: The deal has been booked for the first time and it
-- has been created this month
@ -137,9 +133,7 @@ select
and has_been_booked_within_current_month
)
-- not FTB
and not (
deal_has_first_booking and has_been_booked_within_current_month
)
and not (deal_has_first_booking and has_been_booked_within_current_month)
then '04-Active'
-- 05-Churning: The deal has been booked at least once and it's been 12
-- months since the last booking

View file

@ -29,6 +29,9 @@ select
d.day,
d.date,
d.id_deal,
d.main_deal_name,
d.main_billing_country_iso_3_per_deal,
-- DEAL LIFECYCLE --
deal_lifecycle.deal_lifecycle_state,

View file

@ -484,6 +484,19 @@ models:
tests:
- not_null
- name: main_deal_name
data_type: string
description: |
Main name for this ID deal.
tests:
- not_null
- name: main_billing_country_iso_3_per_deal
data_type: string
description: |
ISO 3166-1 alpha-3 main country code in which the Deal is billed.
In some cases it's null.
- name: int_dates_mtd_by_dimension
description: |
This model provides Month-To-Date (MTD) necessary dates, dimension and dimension_values