From 7717ce3c53adb856adeb67c8f9b93de1341732e3 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 25 Nov 2024 11:53:14 +0100 Subject: [PATCH] Added billing_country --- ...int_kpis__dimension_date_product_guest.sql | 5 +++-- .../int_kpis__product_guest_daily_metrics.sql | 20 ++++++++++++++++--- models/intermediate/kpis/schema.yml | 19 +++++++++++++++++- .../kpis__product_guest_daily_metrics.sql | 1 + models/reporting/kpis/schema.yml | 11 +++++++++- 5 files changed, 49 insertions(+), 7 deletions(-) diff --git a/models/intermediate/kpis/int_kpis__dimension_date_product_guest.sql b/models/intermediate/kpis/int_kpis__dimension_date_product_guest.sql index 58bcc2a..3036a1f 100644 --- a/models/intermediate/kpis/int_kpis__dimension_date_product_guest.sql +++ b/models/intermediate/kpis/int_kpis__dimension_date_product_guest.sql @@ -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") }} diff --git a/models/intermediate/kpis/int_kpis__product_guest_daily_metrics.sql b/models/intermediate/kpis/int_kpis__product_guest_daily_metrics.sql index fd69444..fe7fd7b 100644 --- a/models/intermediate/kpis/int_kpis__product_guest_daily_metrics.sql +++ b/models/intermediate/kpis/int_kpis__product_guest_daily_metrics.sql @@ -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, @@ -81,6 +88,7 @@ select 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, @@ -135,4 +143,10 @@ left join 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.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 diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index 6151ff5..3017f6d 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -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: | diff --git a/models/reporting/kpis/kpis__product_guest_daily_metrics.sql b/models/reporting/kpis/kpis__product_guest_daily_metrics.sql index b0878ef..7a29683 100644 --- a/models/reporting/kpis/kpis__product_guest_daily_metrics.sql +++ b/models/reporting/kpis/kpis__product_guest_daily_metrics.sql @@ -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, diff --git a/models/reporting/kpis/schema.yml b/models/reporting/kpis/schema.yml index 0ab1379..15efcd8 100644 --- a/models/reporting/kpis/schema.yml +++ b/models/reporting/kpis/schema.yml @@ -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: |