Merged PR 2195: Computes GJ with Payment and GJ Payment Rate metrics
Adds the following metrics: - Guest Journey with Payment - Guest Journey Payment Rate by both visions (global and by deal id) **Important**: it does not expose these metrics to the dashboard, this will be done after we have feedback from Ben R. on the paid GJ without GJ completeness. Missing steps to make them appear is to adapt `int_core__mtd_aggregated_metrics` and `int_core__monthly_aggregated_metrics_history_by_deal` and the respective reporting counterparts. It adapts: - `int_core__mtd_guest_journey_metrics` - `int_core__monthly_guest_journey_history_by_deal` the approaches are similar in the sense that we join with `int_core__verification_payments` and filter by a PAID status, that has been defined in the `dbt_project.yml` in a similar manner as we did with cancelled bookings. It can happen that the same verification request has multiple payments (see screenshot), which in this case we keep the first date in which the paid payment happens. The volume is quite low anyway.  code for the screenshot: ``` with pre as ( select id_verification_request, count(distinct icvp.id_payment) as total_paid_payments from intermediate.int_core__verification_payments icvp where icvp.payment_status = 'Paid' group by 1 ) select case when total_paid_payments > 2 then 'more than 2' when total_paid_payments = 2 then '2' when total_paid_payments = 1 then '1' end as payment_volume_category, count(1) as vr_volume from pre group by 1 order by 2 desc ``` I also added a missing reference in `schema.yaml` int about `int_core__mtd_guest_journey_metrics` Related work items: #18105
This commit is contained in:
parent
ed5d7828a7
commit
1781031c9d
4 changed files with 79 additions and 4 deletions
|
|
@ -53,4 +53,8 @@ vars:
|
|||
|
||||
# Booking state variables
|
||||
# States should be strings in capital letters. Models need to force an upper()
|
||||
"cancelled_booking_state": "'CANCELLED'"
|
||||
"cancelled_booking_state": "'CANCELLED'"
|
||||
|
||||
# Payment state variables
|
||||
# States should be strings in capital letters. Models need to force an upper()
|
||||
"paid_payment_state": "'PAID'"
|
||||
|
|
@ -6,9 +6,17 @@ This model provides monthly guest journey metrics for those hosts that have a de
|
|||
|
||||
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_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")}}
|
||||
and vp.id_verification_request is not null
|
||||
group by 1
|
||||
),
|
||||
-- Created Guest Journeys by id_deal --
|
||||
created_year_month as (
|
||||
select
|
||||
|
|
@ -44,6 +52,20 @@ with
|
|||
on u.id_user = vr.id_user_host
|
||||
where u.id_deal is not null
|
||||
group by 1,2
|
||||
),
|
||||
-- Paid Guest Journeys MTD --
|
||||
paid_year_month as (
|
||||
select
|
||||
date_trunc('month', p.first_payment_paid_date_utc)::date as first_day_month,
|
||||
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
|
||||
on vr.id_verification_request = p.id_verification_request
|
||||
where u.id_deal is not null
|
||||
group by 1,2
|
||||
)
|
||||
-- Final aggregation of subqueries + rates computation --
|
||||
select
|
||||
|
|
@ -55,9 +77,11 @@ with
|
|||
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
|
||||
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 paid_rate_guest_journey
|
||||
from int_dates_by_deal d
|
||||
left join created_year_month cym
|
||||
on d.first_day_month = cym.first_day_month
|
||||
|
|
@ -68,4 +92,7 @@ with
|
|||
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
|
||||
|
||||
|
|
@ -5,8 +5,16 @@ This model provides Month-To-Date (MTD) based on Guest Journey metrics.
|
|||
{{ config(materialized="table", unique_key="date") }}
|
||||
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_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||||
|
||||
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
|
||||
),
|
||||
-- Created Guest Journeys MTD --
|
||||
created_year_month as (
|
||||
select d.date, count(distinct vr.id_verification_request) as created_guest_journeys
|
||||
|
|
@ -40,6 +48,17 @@ with
|
|||
and extract(day from vr.verification_estimated_completed_date_utc) <= d.day
|
||||
group by 1
|
||||
),
|
||||
-- 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 extract(year from p.first_payment_paid_date_utc) = d.year
|
||||
and extract(month from p.first_payment_paid_date_utc) = d.month
|
||||
and extract(day from p.first_payment_paid_date_utc) <= d.day
|
||||
group by 1
|
||||
),
|
||||
-- Final aggregation of subqueries + rates computation --
|
||||
main_kpi as (
|
||||
select
|
||||
|
|
@ -52,13 +71,16 @@ with
|
|||
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
|
||||
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_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
|
||||
)
|
||||
-- Pivoting to get previous year for each line & computing relative increment
|
||||
-- (rel_incr) --
|
||||
|
|
@ -82,6 +104,10 @@ select
|
|||
b.completed_guest_journeys as previous_year_completed_guest_journeys,
|
||||
cast(a.completed_guest_journeys as decimal) / b.completed_guest_journeys
|
||||
- 1 as relative_increment_completed_guest_journeys,
|
||||
a.paid_guest_journeys,
|
||||
b.paid_guest_journeys as previous_year_paid_guest_journeys,
|
||||
cast(a.paid_guest_journeys as decimal) / b.paid_guest_journeys
|
||||
- 1 as relative_increment_paid_guest_journeys,
|
||||
a.start_rate_guest_journey,
|
||||
b.start_rate_guest_journey as previous_year_start_rate_guest_journey,
|
||||
cast(a.start_rate_guest_journey as decimal) / b.start_rate_guest_journey
|
||||
|
|
@ -93,7 +119,11 @@ select
|
|||
a.incompletion_rate_guest_journey,
|
||||
b.incompletion_rate_guest_journey as previous_year_incompletion_rate_guest_journey,
|
||||
cast(a.incompletion_rate_guest_journey as decimal) / b.incompletion_rate_guest_journey
|
||||
- 1 as relative_increment_incompletion_rate_guest_journey
|
||||
- 1 as relative_increment_incompletion_rate_guest_journey,
|
||||
a.payment_rate_guest_journey,
|
||||
b.payment_rate_guest_journey as previous_year_payment_rate_guest_journey,
|
||||
cast(a.payment_rate_guest_journey as decimal) / b.payment_rate_guest_journey
|
||||
- 1 as relative_increment_payment_rate_guest_journey
|
||||
from main_kpi a
|
||||
left join main_kpi b on a.month = b.month and a.year = b.year + 1
|
||||
where (a.is_end_of_month = 1 or (a.is_current_month = 1 and a.day = b.day))
|
||||
|
|
@ -265,6 +265,20 @@ models:
|
|||
- not_null
|
||||
- unique
|
||||
|
||||
- name: int_core__mtd_guest_journey_metrics
|
||||
description: |
|
||||
This model contains the historic information regarding the guest journeys in an aggregated manner.
|
||||
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.
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: The date for the month-to-date guest journey-related metrics.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: int_core__mtd_accommodation_metrics
|
||||
description: |
|
||||
This model contains the historic information regarding the accommodations in an aggregated manner.
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue