Merged PR 3476: daily model for guest products
# Description Replacement PR from the abandondes one for daily metrics for guest KPI model # 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. - [ ] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. daily model for guest products Related work items: #23371
This commit is contained in:
commit
b2e9a3e0da
3 changed files with 379 additions and 0 deletions
|
|
@ -0,0 +1,9 @@
|
||||||
|
with
|
||||||
|
unique_dimensions as (
|
||||||
|
select distinct has_payment, has_id_check
|
||||||
|
from {{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }}
|
||||||
|
)
|
||||||
|
select d.date_day, ud.has_payment, ud.has_id_check
|
||||||
|
from {{ ref("int_dates") }} as d
|
||||||
|
cross join unique_dimensions as ud
|
||||||
|
where d.date_day >= {{ var("start_date") }}
|
||||||
|
|
@ -0,0 +1,134 @@
|
||||||
|
{% set has_payment_true = "('With Payment')" %}
|
||||||
|
|
||||||
|
with
|
||||||
|
guest_journey_metrics as (
|
||||||
|
select
|
||||||
|
gj.date,
|
||||||
|
gj.has_payment,
|
||||||
|
gj.has_id_check,
|
||||||
|
sum(
|
||||||
|
gj.created_guest_journeys_not_cancelled
|
||||||
|
) as created_guest_journeys_not_cancelled,
|
||||||
|
sum(
|
||||||
|
gj.started_guest_journeys_not_cancelled
|
||||||
|
) as started_guest_journeys_not_cancelled,
|
||||||
|
sum(
|
||||||
|
gj.completed_guest_journeys_not_cancelled
|
||||||
|
) as completed_guest_journeys_not_cancelled,
|
||||||
|
sum(gj.created_guest_journeys) as created_guest_journeys,
|
||||||
|
sum(gj.started_guest_journeys) as started_guest_journeys,
|
||||||
|
sum(gj.completed_guest_journeys) as completed_guest_journeys,
|
||||||
|
sum(gj.count_csat_score) as total_csat_score_count,
|
||||||
|
case
|
||||||
|
when sum(gj.count_csat_score) > 0
|
||||||
|
then
|
||||||
|
sum(gj.average_csat_score * gj.count_csat_score)
|
||||||
|
/ sum(gj.count_csat_score)
|
||||||
|
else null
|
||||||
|
end as average_csat_score
|
||||||
|
from {{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }} gj
|
||||||
|
group by gj.date, gj.has_payment, gj.has_id_check
|
||||||
|
),
|
||||||
|
guest_payment_metrics as (
|
||||||
|
select
|
||||||
|
gp.date,
|
||||||
|
gp.has_id_check,
|
||||||
|
sum(gp.deposit_fees_in_gbp) as deposit_fees_in_gbp,
|
||||||
|
sum(gp.waiver_payments_in_gbp) as waiver_payments_in_gbp,
|
||||||
|
sum(gp.checkin_cover_fees_in_gbp) as checkin_cover_fees_in_gbp,
|
||||||
|
sum(gp.total_guest_payments_in_gbp) as total_guest_payments_in_gbp
|
||||||
|
from {{ ref("int_kpis__metric_daily_guest_payments") }} gp
|
||||||
|
group by gp.date, gp.has_id_check
|
||||||
|
),
|
||||||
|
guest_kpis as (
|
||||||
|
select
|
||||||
|
dd.date_day,
|
||||||
|
dd.has_payment,
|
||||||
|
dd.has_id_check,
|
||||||
|
gj.created_guest_journeys_not_cancelled,
|
||||||
|
gj.started_guest_journeys_not_cancelled,
|
||||||
|
gj.completed_guest_journeys_not_cancelled,
|
||||||
|
gj.created_guest_journeys,
|
||||||
|
gj.started_guest_journeys,
|
||||||
|
gj.completed_guest_journeys,
|
||||||
|
gj.total_csat_score_count,
|
||||||
|
gj.average_csat_score,
|
||||||
|
gp.deposit_fees_in_gbp,
|
||||||
|
gp.waiver_payments_in_gbp,
|
||||||
|
gp.checkin_cover_fees_in_gbp,
|
||||||
|
gp.total_guest_payments_in_gbp
|
||||||
|
from {{ ref("int_kpis__dimension_date_product_guest") }} dd
|
||||||
|
left join
|
||||||
|
guest_journey_metrics gj
|
||||||
|
on gj.date = dd.date_day
|
||||||
|
and gj.has_payment = dd.has_payment
|
||||||
|
and gj.has_id_check = dd.has_id_check
|
||||||
|
left join
|
||||||
|
guest_payment_metrics gp
|
||||||
|
on gp.date = dd.date_day
|
||||||
|
and gp.has_id_check = dd.has_id_check
|
||||||
|
and dd.has_payment = {{ has_payment_true }}
|
||||||
|
)
|
||||||
|
|
||||||
|
select
|
||||||
|
gk.date_day,
|
||||||
|
gk_py.date_day as py_date_day,
|
||||||
|
gk.has_payment,
|
||||||
|
gk.has_id_check,
|
||||||
|
sum(
|
||||||
|
gk.created_guest_journeys_not_cancelled
|
||||||
|
) as created_guest_journeys_not_cancelled,
|
||||||
|
sum(
|
||||||
|
gk.started_guest_journeys_not_cancelled
|
||||||
|
) as started_guest_journeys_not_cancelled,
|
||||||
|
sum(
|
||||||
|
gk.completed_guest_journeys_not_cancelled
|
||||||
|
) as completed_guest_journeys_not_cancelled,
|
||||||
|
sum(gk.created_guest_journeys) as created_guest_journeys,
|
||||||
|
sum(gk.started_guest_journeys) as started_guest_journeys,
|
||||||
|
sum(gk.completed_guest_journeys) as completed_guest_journeys,
|
||||||
|
sum(gk.total_csat_score_count) as total_csat_score_count,
|
||||||
|
case
|
||||||
|
when sum(gk.total_csat_score_count) > 0
|
||||||
|
then
|
||||||
|
sum(gk.average_csat_score * gk.total_csat_score_count)
|
||||||
|
/ sum(gk.total_csat_score_count)
|
||||||
|
else null
|
||||||
|
end as average_csat_score,
|
||||||
|
sum(gk.deposit_fees_in_gbp) as deposit_fees_in_gbp,
|
||||||
|
sum(gk.waiver_payments_in_gbp) as waiver_payments_in_gbp,
|
||||||
|
sum(gk.checkin_cover_fees_in_gbp) as checkin_cover_fees_in_gbp,
|
||||||
|
sum(gk.total_guest_payments_in_gbp) as total_guest_payments_in_gbp,
|
||||||
|
sum(
|
||||||
|
gk_py.created_guest_journeys_not_cancelled
|
||||||
|
) as py_created_guest_journeys_not_cancelled,
|
||||||
|
sum(
|
||||||
|
gk_py.started_guest_journeys_not_cancelled
|
||||||
|
) as py_started_guest_journeys_not_cancelled,
|
||||||
|
sum(
|
||||||
|
gk_py.completed_guest_journeys_not_cancelled
|
||||||
|
) as py_completed_guest_journeys_not_cancelled,
|
||||||
|
sum(gk_py.created_guest_journeys) as py_created_guest_journeys,
|
||||||
|
sum(gk_py.started_guest_journeys) as py_started_guest_journeys,
|
||||||
|
sum(gk_py.completed_guest_journeys) as py_completed_guest_journeys,
|
||||||
|
sum(gk_py.total_csat_score_count) as py_total_csat_score_count,
|
||||||
|
case
|
||||||
|
when sum(gk_py.total_csat_score_count) > 0
|
||||||
|
then
|
||||||
|
sum(gk_py.average_csat_score * gk_py.total_csat_score_count)
|
||||||
|
/ sum(gk_py.total_csat_score_count)
|
||||||
|
else null
|
||||||
|
end as py_average_csat_score,
|
||||||
|
sum(gk_py.deposit_fees_in_gbp) as py_deposit_fees_in_gbp,
|
||||||
|
sum(gk_py.waiver_payments_in_gbp) as py_waiver_payments_in_gbp,
|
||||||
|
sum(gk_py.checkin_cover_fees_in_gbp) as py_checkin_cover_fees_in_gbp,
|
||||||
|
sum(gk_py.total_guest_payments_in_gbp) as py_total_guest_payments_in_gbp
|
||||||
|
from guest_kpis gk
|
||||||
|
left join
|
||||||
|
guest_kpis gk_py
|
||||||
|
on gk.date_day = gk_py.date_day + interval '1 year'
|
||||||
|
and gk.has_payment = gk_py.has_payment
|
||||||
|
and gk.has_id_check = gk_py.has_id_check
|
||||||
|
-- Here we use a group by because of leap days that generate duplicity when being
|
||||||
|
-- moved to another year
|
||||||
|
group by gk.date_day, gk_py.date_day, gk.has_payment, gk.has_id_check
|
||||||
|
|
@ -5866,3 +5866,239 @@ models:
|
||||||
data_type: bigint
|
data_type: bigint
|
||||||
description: |
|
description: |
|
||||||
Count of listings booked within the past 12 months for a given date, dimension and value.
|
Count of listings booked within the past 12 months for a given date, dimension and value.
|
||||||
|
|
||||||
|
- name: int_kpis__dimension_date_product_guest
|
||||||
|
description: |
|
||||||
|
This model computes a cross join of dates with all combinations of
|
||||||
|
guest products dimensions.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- date_day
|
||||||
|
- has_payment
|
||||||
|
- has_id_check
|
||||||
|
columns:
|
||||||
|
- name: date_day
|
||||||
|
data_type: date
|
||||||
|
description: "Date of when Guest Journeys have been completed."
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: has_payment
|
||||||
|
data_type: string
|
||||||
|
description: Has there been any guest payments on the guest journey.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- W/O Payment
|
||||||
|
- With Payment
|
||||||
|
|
||||||
|
- name: has_id_check
|
||||||
|
data_type: string
|
||||||
|
description: Does the verification in the guest journey
|
||||||
|
includes Government Id Check for the bookings.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- W/O Id Check
|
||||||
|
- With Id Check
|
||||||
|
|
||||||
|
- name: int_kpis__product_guest_daily_metrics
|
||||||
|
description: |
|
||||||
|
This model computes the Daily Guest Metrics at the deepest granularity.
|
||||||
|
Here all metrics are attributed to the Check-in Date of the associated
|
||||||
|
booking, except for payments which are attributed to payment date.
|
||||||
|
|
||||||
|
The unique key corresponds to the deepest granularity of the model,
|
||||||
|
in this case:
|
||||||
|
- date_day,
|
||||||
|
- py_date_day,
|
||||||
|
- id_deal,
|
||||||
|
- has_id_check.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- date_day
|
||||||
|
- py_date_day
|
||||||
|
- has_payment
|
||||||
|
- has_id_check
|
||||||
|
columns:
|
||||||
|
- name: date_day
|
||||||
|
data_type: date
|
||||||
|
description: "Date of when Guest Journeys have been completed."
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: py_date_day
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Date on the previous year of when Guest Journeys have been completed.
|
||||||
|
Note that this date can be NULL for leap days (29th February)
|
||||||
|
|
||||||
|
- name: has_payment
|
||||||
|
data_type: string
|
||||||
|
description: Has there been any guest payments on the guest journey.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- W/O Payment
|
||||||
|
- With Payment
|
||||||
|
|
||||||
|
- name: has_id_check
|
||||||
|
data_type: string
|
||||||
|
description: Does the verification in the guest journey
|
||||||
|
includes Government Id Check for the bookings.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- W/O Id Check
|
||||||
|
- With Id Check
|
||||||
|
|
||||||
|
- name: created_guest_journeys_not_cancelled
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys created, excluding cancelled bookings,
|
||||||
|
in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: started_guest_journeys_not_cancelled
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys started, excluding cancelled bookings,
|
||||||
|
in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: completed_guest_journeys_not_cancelled
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys completed, excluding cancelled bookings,
|
||||||
|
in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: created_guest_journeys
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys created in a given date and
|
||||||
|
per specified dimension.
|
||||||
|
|
||||||
|
- name: started_guest_journeys
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys started in a given date and
|
||||||
|
per specified dimension.
|
||||||
|
|
||||||
|
- name: completed_guest_journeys
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys completed in a given date and
|
||||||
|
per specified dimension.
|
||||||
|
|
||||||
|
- name: count_csat_score
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys with CSAT (customer satisfaction score)
|
||||||
|
in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: average_csat_score
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Average daily CSAT score in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: deposit_fees_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of deposit fees paid by guests, without taxes, in GBP
|
||||||
|
in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: waiver_payments_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of waiver payments paid by guests, without taxes, in GBP
|
||||||
|
in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: checkin_cover_fees_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of checkin cover fees paid by guests, without taxes, in GBP
|
||||||
|
in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: total_guest_payments_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of total payments paid by guests, without taxes, in GBP
|
||||||
|
in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: py_created_guest_journeys_not_cancelled
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys created (excluding canceled bookings)
|
||||||
|
on the same date in the previous year, segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_started_guest_journeys_not_cancelled
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys started (excluding canceled bookings)
|
||||||
|
on the same date in the previous year, segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_completed_guest_journeys_not_cancelled
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys completed (excluding canceled bookings)
|
||||||
|
on the same date in the previous year, segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_created_guest_journeys
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys created on the same date in the previous year,
|
||||||
|
segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_started_guest_journeys
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys started on the same date in the previous year,
|
||||||
|
segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_completed_guest_journeys
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys completed on the same date in the previous year,
|
||||||
|
segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_count_csat_score
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily guest journeys with CSAT (customer satisfaction score)
|
||||||
|
on the same date in the previous year, segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_average_csat_score
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Average daily CSAT score on the same date in the previous year,
|
||||||
|
segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_deposit_fees_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of deposit fees paid by guests, excluding taxes, in GBP
|
||||||
|
on the same date in the previous year, segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_waiver_payments_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of waiver payments paid by guests, excluding taxes, in GBP
|
||||||
|
on the same date in the previous year, segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_checkin_cover_fees_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of check-in cover fees paid by guests, excluding taxes, in GBP
|
||||||
|
on the same date in the previous year, segmented by the specified dimension.
|
||||||
|
|
||||||
|
- name: py_total_guest_payments_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of total payments paid by guests, excluding taxes, in GBP
|
||||||
|
on the same date in the previous year, segmented by the specified dimension.
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue