From 7717ce3c53adb856adeb67c8f9b93de1341732e3 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 25 Nov 2024 11:53:14 +0100 Subject: [PATCH 1/6] 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: | From de2cb8264b4167b387298420670fa7ed220f04ef Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 25 Nov 2024 16:17:12 +0100 Subject: [PATCH 2/6] fixed join for billing_countries and created new model for timeframe aggregations --- .../int_kpis__product_guest_agg_metrics.sql | 144 ++++++++++++++++++ .../int_kpis__product_guest_daily_metrics.sql | 18 ++- 2 files changed, 155 insertions(+), 7 deletions(-) create mode 100644 models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql diff --git a/models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql b/models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql new file mode 100644 index 0000000..6df0436 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql @@ -0,0 +1,144 @@ +{% 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", + "average_csat_score", + "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') + + interval '1 day' + * extract( + dow from {{ yesterday }} - interval '1 day' + ) 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 py_current_date, + {{ yesterday }} - interval '1 month' as pm_current_date, + {{ yesterday }} - interval '1 week' as pw_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.py_current_date + then dm.{{ metric }} + end + ) as py_value, + sum( + case + when date_day between dr.py_year_start and dr.py_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.py_current_date + then dm.{{ metric }} + end + ) as py_value, + sum( + case + when date_day between dr.pp_month_start and dr.pm_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.pw_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 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 fe7fd7b..e12da71 100644 --- a/models/intermediate/kpis/int_kpis__product_guest_daily_metrics.sql +++ b/models/intermediate/kpis/int_kpis__product_guest_daily_metrics.sql @@ -1,5 +1,3 @@ -{% set has_payment_true = "('With Payment')" %} - with guest_journey_metrics as ( select @@ -27,7 +25,8 @@ with / sum(gj.count_csat_score) else null end as average_csat_score - from {{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }} gj + from + "intermediate"."int_kpis__metric_daily_check_in_attributed_guest_journeys" gj group by gj.date, gj.has_payment, @@ -43,7 +42,7 @@ with 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 + from "intermediate"."int_kpis__metric_daily_guest_payments" gp where gp.date < current_date group by gp.date, gp.has_id_check, gp.main_billing_country_iso_3_per_deal ), @@ -66,22 +65,25 @@ with 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 + from "intermediate"."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 + 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 dd.has_payment = ('With Payment') + 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, @@ -141,6 +143,8 @@ 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 From b355d8cbc74d5182955842b1efa901058b23b5ad Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 25 Nov 2024 16:32:21 +0100 Subject: [PATCH 3/6] Added schema of new model --- models/intermediate/kpis/schema.yml | 79 +++++++++++++++++++++++++++++ 1 file changed, 79 insertions(+) diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index 3017f6d..107d50d 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -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. From 2404905da1c45675d3f286613758c2a4bd65aa6a Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Tue, 26 Nov 2024 09:33:31 +0100 Subject: [PATCH 4/6] Removed agg model --- .../int_kpis__product_guest_agg_metrics.sql | 144 ------------------ 1 file changed, 144 deletions(-) delete mode 100644 models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql diff --git a/models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql b/models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql deleted file mode 100644 index 6df0436..0000000 --- a/models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql +++ /dev/null @@ -1,144 +0,0 @@ -{% 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", - "average_csat_score", - "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') - + interval '1 day' - * extract( - dow from {{ yesterday }} - interval '1 day' - ) 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 py_current_date, - {{ yesterday }} - interval '1 month' as pm_current_date, - {{ yesterday }} - interval '1 week' as pw_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.py_current_date - then dm.{{ metric }} - end - ) as py_value, - sum( - case - when date_day between dr.py_year_start and dr.py_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.py_current_date - then dm.{{ metric }} - end - ) as py_value, - sum( - case - when date_day between dr.pp_month_start and dr.pm_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.pw_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 From 6b5b7d2d5a21ae668ef73f31511b43ad08ad5b8c Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Tue, 26 Nov 2024 09:54:35 +0100 Subject: [PATCH 5/6] fixed model copy paste --- .../kpis/int_kpis__product_guest_daily_metrics.sql | 11 ++++++----- 1 file changed, 6 insertions(+), 5 deletions(-) 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 e12da71..fd83fca 100644 --- a/models/intermediate/kpis/int_kpis__product_guest_daily_metrics.sql +++ b/models/intermediate/kpis/int_kpis__product_guest_daily_metrics.sql @@ -1,3 +1,5 @@ +{% set has_payment_true = "('With Payment')" %} + with guest_journey_metrics as ( select @@ -25,8 +27,7 @@ with / sum(gj.count_csat_score) else null end as average_csat_score - from - "intermediate"."int_kpis__metric_daily_check_in_attributed_guest_journeys" gj + from {{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }} gj group by gj.date, gj.has_payment, @@ -42,7 +43,7 @@ with 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 "intermediate"."int_kpis__metric_daily_guest_payments" gp + from {{ ref("int_kpis__metric_daily_guest_payments") }} gp where gp.date < current_date group by gp.date, gp.has_id_check, gp.main_billing_country_iso_3_per_deal ), @@ -65,7 +66,7 @@ with gp.waiver_payments_in_gbp, gp.checkin_cover_fees_in_gbp, gp.total_guest_payments_in_gbp - from "intermediate"."int_kpis__dimension_date_product_guest" dd + from {{ ref("int_kpis__dimension_date_product_guest") }} dd left join guest_journey_metrics gj on gj.date = dd.date_day @@ -77,7 +78,7 @@ with guest_payment_metrics gp on gp.date = dd.date_day and gp.has_id_check = dd.has_id_check - and dd.has_payment = ('With Payment') + 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 From 68644630d4a771baa2117baa42559605a8f8d118 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Tue, 26 Nov 2024 11:20:25 +0100 Subject: [PATCH 6/6] rebase and updated schema --- models/intermediate/kpis/schema.yml | 79 ----------------------------- 1 file changed, 79 deletions(-) diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index 107d50d..3017f6d 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -5304,85 +5304,6 @@ 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.