Merged PR 3666: Aggregated model for guest kpis metrics in intermediate
# Description Aggregated model for guest kpis metrics. This model aggregates the values for all basic metrics for guest kpis, it has a granularity per metrics of timeframe (YTD, MTD, WTD) and all other dimensions needed (has_payment, has_id_check & main_billing_country_iso_3_per_deal). I decided not to include the calculated metrics because it adds much more complexity to the model specially when you start considering all possible combinations between dimensions and how this would affect the calculations, in this case conversion_rate, revenue_rate and average_csat_score. I think this could all be managed much simpler inside PBI and since the granularity of the model is not as deep as the daily model, this should help with the loading time for the report. # 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. - [ ] 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. Related work items: #24604
This commit is contained in:
commit
dd4dff1479
2 changed files with 220 additions and 0 deletions
141
models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql
Normal file
141
models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql
Normal file
|
|
@ -0,0 +1,141 @@
|
|||
{% set yesterday = "(current_date - interval '1 day')" %}
|
||||
{% set metric_names = (
|
||||
"created_guest_journeys_not_cancelled",
|
||||
"started_guest_journeys_not_cancelled",
|
||||
"completed_guest_journeys_not_cancelled",
|
||||
"created_guest_journeys",
|
||||
"started_guest_journeys",
|
||||
"completed_guest_journeys",
|
||||
"total_csat_score_count",
|
||||
"deposit_fees_in_gbp",
|
||||
"waiver_payments_in_gbp",
|
||||
"checkin_cover_fees_in_gbp",
|
||||
"total_guest_payments_in_gbp",
|
||||
) %}
|
||||
|
||||
with
|
||||
int_kpis__product_guest_daily_metrics as (
|
||||
select
|
||||
date_day,
|
||||
has_payment,
|
||||
has_id_check,
|
||||
main_billing_country_iso_3_per_deal,
|
||||
{% for metric in metric_names %}
|
||||
{{ metric }}{% if not loop.last %},{% endif %}
|
||||
{% endfor %}
|
||||
from {{ ref("int_kpis__product_guest_daily_metrics") }}
|
||||
),
|
||||
date_ranges as (
|
||||
select
|
||||
{{ yesterday }} as current_date,
|
||||
date_trunc('month', {{ yesterday }}) as current_month_start,
|
||||
date_trunc('week', {{ yesterday }}) as current_week_start, -- Start of the current week
|
||||
date_trunc('week', {{ yesterday }} - interval '1 year') as py_week_start, -- Start of the same week last year
|
||||
date_trunc('week', {{ yesterday }} - interval '1 year') + (
|
||||
{{ yesterday }} - date_trunc('week', {{ yesterday }})
|
||||
) as py_week_current_date,
|
||||
date_trunc('week', {{ yesterday }} - interval '1 week') as pp_week_start, -- Start of the same week in the previous period
|
||||
date_trunc('month', {{ yesterday }} - interval '1 year') as py_month_start,
|
||||
date_trunc('year', {{ yesterday }}) as current_year_start,
|
||||
date_trunc('year', {{ yesterday }} - interval '1 year') as py_year_start,
|
||||
date_trunc('month', {{ yesterday }} - interval '1 month') as pp_month_start,
|
||||
{{ yesterday }} - interval '1 year' as ppy_current_date,
|
||||
{{ yesterday }} - interval '1 month' as ppm_current_date,
|
||||
{{ yesterday }} - interval '1 week' as ppw_current_date,
|
||||
extract(day from {{ yesterday }}) as current_day_of_month
|
||||
|
||||
),
|
||||
aggregated_metrics as (
|
||||
{% for metric in metric_names %}
|
||||
select
|
||||
'{{ metric }}' as metric,
|
||||
has_payment,
|
||||
has_id_check,
|
||||
main_billing_country_iso_3_per_deal,
|
||||
'YTD' as timeframe,
|
||||
sum(
|
||||
case
|
||||
when date_day between dr.current_year_start and {{ yesterday }}
|
||||
then dm.{{ metric }}
|
||||
end
|
||||
) as current_value,
|
||||
sum(
|
||||
case
|
||||
when date_day between dr.py_year_start and dr.ppy_current_date
|
||||
then dm.{{ metric }}
|
||||
end
|
||||
) as py_value,
|
||||
sum(
|
||||
case
|
||||
when date_day between dr.py_year_start and dr.ppy_current_date
|
||||
then dm.{{ metric }}
|
||||
end
|
||||
) as pp_value
|
||||
from int_kpis__product_guest_daily_metrics dm, date_ranges dr
|
||||
where extract(day from date_day) <= dr.current_day_of_month
|
||||
group by
|
||||
metric, has_payment, has_id_check, main_billing_country_iso_3_per_deal
|
||||
union all
|
||||
select
|
||||
'{{ metric }}' as metric,
|
||||
has_payment,
|
||||
has_id_check,
|
||||
main_billing_country_iso_3_per_deal,
|
||||
'MTD' as timeframe,
|
||||
sum(
|
||||
case
|
||||
when date_day between dr.current_month_start and {{ yesterday }}
|
||||
then dm.{{ metric }}
|
||||
end
|
||||
) as current_value,
|
||||
sum(
|
||||
case
|
||||
when date_day between dr.py_month_start and dr.ppy_current_date
|
||||
then dm.{{ metric }}
|
||||
end
|
||||
) as py_value,
|
||||
sum(
|
||||
case
|
||||
when date_day between dr.pp_month_start and dr.ppm_current_date
|
||||
then dm.{{ metric }}
|
||||
end
|
||||
) as pp_value
|
||||
from int_kpis__product_guest_daily_metrics dm, date_ranges dr
|
||||
where extract(day from date_day) <= dr.current_day_of_month
|
||||
group by
|
||||
metric, has_payment, has_id_check, main_billing_country_iso_3_per_deal
|
||||
union all
|
||||
select
|
||||
'{{ metric }}' as metric,
|
||||
has_payment,
|
||||
has_id_check,
|
||||
main_billing_country_iso_3_per_deal,
|
||||
'WTD' as timeframe,
|
||||
sum(
|
||||
case
|
||||
when date_day between dr.current_week_start and {{ yesterday }}
|
||||
then dm.{{ metric }}
|
||||
end
|
||||
) as current_value,
|
||||
sum(
|
||||
case
|
||||
when date_day between dr.py_week_start and py_week_current_date
|
||||
then dm.{{ metric }}
|
||||
end
|
||||
) as py_value,
|
||||
sum(
|
||||
case
|
||||
when date_day between dr.pp_week_start and dr.ppw_current_date
|
||||
then dm.{{ metric }}
|
||||
end
|
||||
) as pp_value
|
||||
from int_kpis__product_guest_daily_metrics dm, date_ranges dr
|
||||
group by
|
||||
metric, has_payment, has_id_check, main_billing_country_iso_3_per_deal
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
)
|
||||
select *
|
||||
from aggregated_metrics
|
||||
|
|
@ -5304,6 +5304,85 @@ models:
|
|||
Sum of total payments paid by guests, excluding taxes, in GBP
|
||||
on the same date in the previous year, segmented by the specified dimension.
|
||||
|
||||
- name: int_kpis__product_guest_agg_metrics
|
||||
description:
|
||||
This model aggregates multiple metrics on a Year-to-date, Month-to-date or
|
||||
Week-to-date basis. This model changes the display format of the model
|
||||
int_kpis__product_guest_daily_metrics pivoting the metrics columns and
|
||||
adding a timeframe dimension.
|
||||
columns:
|
||||
- name: metric
|
||||
data_type: text
|
||||
description: Name of the business metric
|
||||
|
||||
- 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: main_billing_country_iso_3_per_deal
|
||||
data_type: string
|
||||
description: |
|
||||
Main billing country of the host aggregated at Deal level.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: timeframe
|
||||
data_type: text
|
||||
description: |
|
||||
Timeframe considered for the aggregation, it could be Year-to-date,
|
||||
Month-to-date or Week-to-date
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- YTD
|
||||
- MTD
|
||||
- WTD
|
||||
|
||||
- name: current_value
|
||||
data_type: numeric
|
||||
description: |
|
||||
Numeric value (integer or decimal) that corresponds to the timeframe
|
||||
computation of the metric at the current date.
|
||||
For example if the current date is 27/11/2024 and the timeframe is MTD,
|
||||
then this value would correspond to the computation of the metric for
|
||||
the dates between 01/11/2024 and 27/11/2024.
|
||||
|
||||
- name: py_value
|
||||
data_type: numeric
|
||||
description: |
|
||||
Numeric value (integer or decimal) that corresponds to the timeframe
|
||||
computation of the metric at the current date but on the previous year.
|
||||
For example if the current date is 27/11/2024 and the timeframe is MTD,
|
||||
then this value would correspond to the computation of the metric for
|
||||
the dates between 01/11/2023 and 27/11/2023.
|
||||
|
||||
- name: pp_value
|
||||
data_type: numeric
|
||||
description: |
|
||||
Numeric value (integer or decimal) that corresponds to the timeframe
|
||||
computation of the metric at the current date but on the previous period.
|
||||
For example if the current date is 27/11/2024 and the timeframe is MTD,
|
||||
then this value would correspond to the computation of the metric for
|
||||
the dates between 01/10/2024 and 27/10/2024.
|
||||
|
||||
- name: int_kpis__metric_daily_new_dash_created_services
|
||||
description: |
|
||||
This model computes the Daily Created Services at the deepest granularity.
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue