Merged PR 3651: Adding billing_country as dimension and new aggregated model
# Description Added billing_country as dimension to use in the Guest KPIs Report. Also created a new model that pivots the metrics to leave them as a column and aggregates the values set for different timeframes (YTD, MTD, WTD). For the moment it only aggregates the values for the existing metrics on the existing models, it doesn't compute metrics like rates or averages (avg_csat_score, conversion_rate, etc..). I am not sure if it would be better to compute here in the model or just doing it in PBI, both are viable options not sure if the model is going to end up being too monstrous or it doesn't matter. @<Oriol Roqué Paniagua> what do you think?? Imagen para ayudar a entender el modelo  # 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. - [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: #24604
This commit is contained in:
commit
b7c5a526f7
5 changed files with 55 additions and 8 deletions
|
|
@ -1,6 +1,6 @@
|
|||
with
|
||||
unique_dimensions as (
|
||||
select distinct has_payment, has_id_check
|
||||
select distinct has_payment, has_id_check, main_billing_country_iso_3_per_deal
|
||||
from {{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }}
|
||||
)
|
||||
select
|
||||
|
|
@ -11,7 +11,8 @@ select
|
|||
else concat('Week-', d.iso_week_of_year)
|
||||
end as date_week,
|
||||
ud.has_payment,
|
||||
ud.has_id_check
|
||||
ud.has_id_check,
|
||||
ud.main_billing_country_iso_3_per_deal
|
||||
from {{ ref("int_dates") }} as d
|
||||
cross join unique_dimensions as ud
|
||||
where d.date_day >= {{ var("start_date") }}
|
||||
|
|
|
|||
|
|
@ -6,6 +6,7 @@ with
|
|||
gj.date,
|
||||
gj.has_payment,
|
||||
gj.has_id_check,
|
||||
gj.main_billing_country_iso_3_per_deal,
|
||||
sum(
|
||||
gj.created_guest_journeys_not_cancelled
|
||||
) as created_guest_journeys_not_cancelled,
|
||||
|
|
@ -27,19 +28,24 @@ with
|
|||
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
|
||||
group by
|
||||
gj.date,
|
||||
gj.has_payment,
|
||||
gj.has_id_check,
|
||||
gj.main_billing_country_iso_3_per_deal
|
||||
),
|
||||
guest_payment_metrics as (
|
||||
select
|
||||
gp.date,
|
||||
gp.has_id_check,
|
||||
gp.main_billing_country_iso_3_per_deal,
|
||||
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
|
||||
where gp.date < current_date
|
||||
group by gp.date, gp.has_id_check
|
||||
group by gp.date, gp.has_id_check, gp.main_billing_country_iso_3_per_deal
|
||||
),
|
||||
guest_kpis as (
|
||||
select
|
||||
|
|
@ -47,6 +53,7 @@ with
|
|||
dd.date_week,
|
||||
dd.has_payment,
|
||||
dd.has_id_check,
|
||||
dd.main_billing_country_iso_3_per_deal,
|
||||
gj.created_guest_journeys_not_cancelled,
|
||||
gj.started_guest_journeys_not_cancelled,
|
||||
gj.completed_guest_journeys_not_cancelled,
|
||||
|
|
@ -65,22 +72,26 @@ with
|
|||
on gj.date = dd.date_day
|
||||
and gj.has_payment = dd.has_payment
|
||||
and gj.has_id_check = dd.has_id_check
|
||||
and gj.main_billing_country_iso_3_per_deal
|
||||
= dd.main_billing_country_iso_3_per_deal
|
||||
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 }}
|
||||
and gp.main_billing_country_iso_3_per_deal
|
||||
= dd.main_billing_country_iso_3_per_deal
|
||||
-- Restricts the records by date being in the past or in the next following 12
|
||||
-- months
|
||||
where dd.date_day <= current_date + interval '1 year'
|
||||
)
|
||||
|
||||
select
|
||||
gk.date_day,
|
||||
gk.date_week,
|
||||
gk_py.date_day as py_date_day,
|
||||
gk.has_payment,
|
||||
gk.has_id_check,
|
||||
gk.main_billing_country_iso_3_per_deal,
|
||||
sum(
|
||||
gk.created_guest_journeys_not_cancelled
|
||||
) as created_guest_journeys_not_cancelled,
|
||||
|
|
@ -133,6 +144,14 @@ left join
|
|||
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
|
||||
and gk.main_billing_country_iso_3_per_deal
|
||||
= gk_py.main_billing_country_iso_3_per_deal
|
||||
-- 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.date_week, gk_py.date_day, gk.has_payment, gk.has_id_check
|
||||
group by
|
||||
gk.date_day,
|
||||
gk.date_week,
|
||||
gk_py.date_day,
|
||||
gk.has_payment,
|
||||
gk.has_id_check,
|
||||
gk.main_billing_country_iso_3_per_deal
|
||||
|
|
|
|||
|
|
@ -5050,6 +5050,7 @@ models:
|
|||
- date_day
|
||||
- has_payment
|
||||
- has_id_check
|
||||
- main_billing_country_iso_3_per_deal
|
||||
columns:
|
||||
- name: date_day
|
||||
data_type: date
|
||||
|
|
@ -5084,6 +5085,13 @@ models:
|
|||
- 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.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_kpis__product_guest_daily_metrics
|
||||
description: |
|
||||
This model computes the Daily Guest Metrics at the deepest granularity.
|
||||
|
|
@ -5095,7 +5103,8 @@ models:
|
|||
- date_day,
|
||||
- py_date_day,
|
||||
- id_deal,
|
||||
- has_id_check.
|
||||
- has_id_check,
|
||||
- main_billing_country_iso_3_per_deal.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
|
|
@ -5104,6 +5113,7 @@ models:
|
|||
- py_date_day
|
||||
- has_payment
|
||||
- has_id_check
|
||||
- main_billing_country_iso_3_per_deal
|
||||
columns:
|
||||
- name: date_day
|
||||
data_type: date
|
||||
|
|
@ -5144,6 +5154,13 @@ models:
|
|||
- 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.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys_not_cancelled
|
||||
data_type: bigint
|
||||
description: |
|
||||
|
|
|
|||
|
|
@ -9,6 +9,7 @@ select
|
|||
py_date_day as py_date_day,
|
||||
has_payment as has_payment,
|
||||
has_id_check as has_id_check,
|
||||
main_billing_country_iso_3_per_deal as main_billing_country_iso_3_per_deal,
|
||||
created_guest_journeys_not_cancelled as created_guest_journeys_not_cancelled,
|
||||
started_guest_journeys_not_cancelled as started_guest_journeys_not_cancelled,
|
||||
completed_guest_journeys_not_cancelled as completed_guest_journeys_not_cancelled,
|
||||
|
|
|
|||
|
|
@ -12,7 +12,8 @@ models:
|
|||
- date_day,
|
||||
- py_date_day,
|
||||
- id_deal,
|
||||
- has_id_check.
|
||||
- has_id_check,
|
||||
- main_billing_country_iso_3_per_deal.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
|
|
@ -21,6 +22,7 @@ models:
|
|||
- py_date_day
|
||||
- has_payment
|
||||
- has_id_check
|
||||
- main_billing_country_iso_3_per_deal
|
||||
columns:
|
||||
- name: date_day
|
||||
data_type: date
|
||||
|
|
@ -61,6 +63,13 @@ models:
|
|||
- 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.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys_not_cancelled
|
||||
data_type: bigint
|
||||
description: |
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue