From e1d04c2e4e5ec6eac4ba6a1b907595b96efa823b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Mon, 19 Aug 2024 11:45:42 +0000 Subject: [PATCH] Merged PR 2580: Guest Payments metrics per customer segmentation # Description Modifies `int_core__mtd_guest_payments_metrics` to include the customer segmentation based on listings. `schema.yaml` is also affected including new fields, tests and apply the proper naming (from guest revenue to guest payments). I also modified a silly naming that was referring to deals to refer to listings/accommodations, my bad. Added the macro to retrieve the production dimension in `int_core__mtd_vs_previous_year_metrics` to avoid propagating this upwards and messing up with the data display. Overall, follows a similar strategy as we did for Booking, Guest Journey, Deal and Accommodation metrics. For reference, [here's the previous PR on Accommodations](https://guardhog.visualstudio.com/Data/_git/data-dwh-dbt-project/pullrequest/2575?_a=overview). # 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. - [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: #19325 --- .../int_core__mtd_guest_payments_metrics.sql | 111 ++++++++++++------ models/intermediate/core/schema.yaml | 29 ++++- .../int_mtd_vs_previous_year_metrics.sql | 1 + 3 files changed, 99 insertions(+), 42 deletions(-) diff --git a/models/intermediate/core/int_core__mtd_guest_payments_metrics.sql b/models/intermediate/core/int_core__mtd_guest_payments_metrics.sql index aa650b8..eef598d 100644 --- a/models/intermediate/core/int_core__mtd_guest_payments_metrics.sql +++ b/models/intermediate/core/int_core__mtd_guest_payments_metrics.sql @@ -2,6 +2,8 @@ This model provides Month-To-Date (MTD) based on Guest Revenue metrics. */ +{% set dimensions = get_kpi_dimensions() %} + {% set deposit_fees_verification_payment_type_items = "('FEE')" %} {% set waiver_fees_verification_payment_type_items = "('WAIVER')" %} {% set checkin_cover_fees_verification_payment_type_items = "('CHECKINCOVER')" %} @@ -11,46 +13,73 @@ with int_core__verification_payments as ( select * from {{ ref("int_core__verification_payments") }} ), + int_core__verification_requests as ( + select * from {{ ref("int_core__verification_requests") }} + ), + int_core__user_host as (select * from {{ ref("int_core__user_host") }}), + int_core__mtd_accommodation_segmentation as ( + select * from {{ ref("int_core__mtd_accommodation_segmentation") }} + ), + int_dates_mtd_by_dimension as ( + select * from {{ ref("int_dates_mtd_by_dimension") }} + ), int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}), -- Paid Guest Revenue MTD -- guest_payments_year_month as ( - select - d.date, - sum( - case - when - upper(vp.verification_payment_type) - in {{ deposit_fees_verification_payment_type_items }} - then vp.amount_in_gbp - else null - end - ) as deposit_fees_in_gbp, - sum( - case - when - upper(vp.verification_payment_type) - in {{ waiver_fees_verification_payment_type_items }} - then vp.amount_in_gbp - else null - end - ) as waiver_payments_in_gbp, - sum( - case - when - upper(vp.verification_payment_type) - in {{ checkin_cover_fees_verification_payment_type_items }} - then vp.amount_in_gbp - else null - end - ) as checkin_cover_fees_in_gbp - from int_dates_mtd d - inner join - int_core__verification_payments vp - on date_trunc('month', vp.payment_paid_date_utc)::date = d.first_day_month - and extract(day from vp.payment_paid_date_utc) <= d.day - where upper(vp.payment_status) = {{ var("paid_payment_state") }} - group by 1 + {% for dimension in dimensions %} + select + d.date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + sum( + case + when + upper(vp.verification_payment_type) + in {{ deposit_fees_verification_payment_type_items }} + then vp.amount_in_gbp + else null + end + ) as deposit_fees_in_gbp, + sum( + case + when + upper(vp.verification_payment_type) + in {{ waiver_fees_verification_payment_type_items }} + then vp.amount_in_gbp + else null + end + ) as waiver_payments_in_gbp, + sum( + case + when + upper(vp.verification_payment_type) + in {{ checkin_cover_fees_verification_payment_type_items }} + then vp.amount_in_gbp + else null + end + ) as checkin_cover_fees_in_gbp + from int_dates_mtd d + inner join + int_core__verification_payments vp + on date_trunc('month', vp.payment_paid_date_utc)::date = d.first_day_month + and extract(day from vp.payment_paid_date_utc) <= d.day + {% if dimension.dimension == "'by_number_of_listings'" %} + inner join + int_core__verification_requests vr + on vp.id_verification_request = vr.id_verification_request + inner join int_core__user_host u on vr.id_user_host = u.id_user_host + inner join + int_core__mtd_accommodation_segmentation mas + on u.id_deal = mas.id_deal + and d.date = mas.date + {% endif %} + where upper(vp.payment_status) = {{ var("paid_payment_state") }} + group by 1, 2, 3 + {% if not loop.last %} + union all + {% endif %} + {% endfor %} ) -- Final aggregation of subqueries -- select @@ -58,6 +87,8 @@ select d.month, d.day, d.date, + d.dimension, + d.dimension_value, d.is_end_of_month, d.is_current_month, nullif(gpym.deposit_fees_in_gbp, 0) as deposit_fees_in_gbp, @@ -69,5 +100,9 @@ select + coalesce(gpym.checkin_cover_fees_in_gbp, 0), 0 ) as total_guest_payments_in_gbp -from int_dates_mtd d -left join guest_payments_year_month gpym on gpym.date = d.date +from int_dates_mtd_by_dimension d +left join + guest_payments_year_month gpym + on gpym.date = d.date + and gpym.dimension = d.dimension + and gpym.dimension_value = d.dimension_value diff --git a/models/intermediate/core/schema.yaml b/models/intermediate/core/schema.yaml index 301e815..b99ab42 100644 --- a/models/intermediate/core/schema.yaml +++ b/models/intermediate/core/schema.yaml @@ -307,7 +307,7 @@ models: columns: - name: date data_type: date - description: The date for the month-to-date deal-related metrics. + description: The date for the month-to-date accommodation-related metrics. tests: - not_null @@ -363,17 +363,38 @@ models: - name: int_core__mtd_guest_payments_metrics description: | - This model contains the historic information regarding the guest revenue in an aggregated manner. + This model contains the historic information regarding the guest payments in an aggregated manner. It's used for the business KPIs. Data is aggregated at the last day of the month and in the days necessary for the Month-to-Date computation of the current month. + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - dimension + - dimension_value + columns: - name: date data_type: date - description: The date for the month-to-date guest revenue-related metrics. + description: The date for the month-to-date guest payments-related metrics. + tests: + - not_null + + - name: dimension + data_type: string + description: The dimension or granularity of the metrics. + tests: + - accepted_values: + values: + - global + - by_number_of_listings + + - name: dimension_value + data_type: string + description: The value or segment available for the selected dimension. tests: - not_null - - unique - name: int_core__monthly_guest_payments_history_by_deal description: | diff --git a/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql b/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql index a982f6f..9edcbac 100644 --- a/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql +++ b/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql @@ -25,6 +25,7 @@ with ), int_core__mtd_guest_payments_metrics as ( select * from {{ ref("int_core__mtd_guest_payments_metrics") }} + where dimension in ({{ production_dimensions }}) ), int_xero__mtd_invoicing_metrics as ( select * from {{ ref("int_xero__mtd_invoicing_metrics") }}