From 098ab514396af340cf3895f9b7e52ec9539bb044 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Thu, 20 Mar 2025 13:45:44 +0000 Subject: [PATCH] Merged PR 4757: Creates a Total Booking Fees metric (Old dash + New dash) # Description Main Changes: * Computes the total booking fees in `int_kpis__metric_daily_invoiced_revenue` * Propagates within KPIs, including schema and tests * Propagates within cross in both "by deal" and "by dimension/global" * Propagates to main kpis tests Small fix: * In `int_mtd_vs_previous_year_metrics`, manual formatting because sqlfmt is broken on this model... # 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: #28560 --- ...hly_aggregated_metrics_history_by_deal.sql | 1 + .../cross/int_mtd_aggregated_metrics.sql | 9 +++++ .../int_mtd_vs_previous_year_metrics.sql | 30 +++++++++++++-- ...int_kpis__agg_monthly_invoiced_revenue.sql | 1 + .../int_kpis__agg_mtd_invoiced_revenue.sql | 1 + ...nt_kpis__metric_daily_invoiced_revenue.sql | 21 ++++++++++- ..._kpis__metric_monthly_invoiced_revenue.sql | 1 + .../int_kpis__metric_mtd_invoiced_revenue.sql | 1 + models/intermediate/kpis/schema.yml | 37 +++++++++++++++++++ ...hly_aggregated_metrics_history_by_deal.sql | 5 +-- ...e_metrics_per_dimension_are_consistent.sql | 1 + .../kpis_global_metrics_outlier_detection.sql | 1 + 12 files changed, 101 insertions(+), 8 deletions(-) diff --git a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql index 73ce54a..f755bcc 100644 --- a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql +++ b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql @@ -166,6 +166,7 @@ select invoiced_revenue.xero_sex_offenders_check_net_fees_in_gbp, invoiced_revenue.xero_protection_pro_net_fees_in_gbp, -- GLOBAL -- + invoiced_revenue.xero_booking_net_fees_in_gbp, invoiced_revenue.xero_operator_net_fees_in_gbp, -- APIs REVENUE -- diff --git a/models/intermediate/cross/int_mtd_aggregated_metrics.sql b/models/intermediate/cross/int_mtd_aggregated_metrics.sql index 820830b..ab5ee47 100644 --- a/models/intermediate/cross/int_mtd_aggregated_metrics.sql +++ b/models/intermediate/cross/int_mtd_aggregated_metrics.sql @@ -422,6 +422,15 @@ "number_format": "currency_gbp", "increment_sign_format": "positive", }, + { + "order_by": 224, + "metric": "Invoiced Total Booking Fees Revenue", + "value": "xero_booking_net_fees_in_gbp", + "previous_year_value": "previous_year_xero_booking_net_fees_in_gbp", + "relative_increment": "relative_increment_xero_booking_net_fees_in_gbp", + "number_format": "currency_gbp", + "increment_sign_format": "positive", + }, { "order_by": 225, "metric": "Invoiced Old Dashboard Booking Fees Revenue", 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 3f9710c..6c81f1e 100644 --- a/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql +++ b/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql @@ -252,6 +252,7 @@ with invoiced_revenue.xero_sex_offenders_check_net_fees_in_gbp, invoiced_revenue.xero_protection_pro_net_fees_in_gbp, -- GLOBAL -- + invoiced_revenue.xero_booking_net_fees_in_gbp, invoiced_revenue.xero_operator_net_fees_in_gbp, -- APIs REVENUE -- @@ -267,7 +268,8 @@ with as host_resolution_amount_paid_per_created_booking, {{ return_capped_value( - "cast(host_resolutions.xero_host_resolution_payment_count as decimal) / created_bookings.created_bookings", + "cast(host_resolutions.xero_host_resolution_payment_count as decimal) + / created_bookings.created_bookings", -1, 1, ) @@ -349,7 +351,17 @@ with ) as revenue_retained_in_gbp, {{ return_capped_value( - "nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0), 0 ) / nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0), 0 )", + "nullif( + coalesce(guest_payments.total_guest_payments_in_gbp, 0) + + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) + + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0) + ,0) + / nullif( + coalesce(guest_payments.total_guest_payments_in_gbp, 0) + + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) + ,0)", -1, 1, ) @@ -367,7 +379,18 @@ with ) as revenue_retained_post_resolutions_in_gbp, {{ return_capped_value( - "nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0) + coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0), 0 ) / nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0), 0 )", + "nullif( + coalesce(guest_payments.total_guest_payments_in_gbp, 0) + + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) + + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0) + + coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0) + ,0) + / nullif( + coalesce(guest_payments.total_guest_payments_in_gbp, 0) + + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0), + 0)", -1, 1, ) @@ -533,6 +556,7 @@ select {{ calculate_safe_relative_increment("xero_sex_offenders_check_net_fees_in_gbp") }}, {{ calculate_safe_relative_increment("xero_protection_pro_net_fees_in_gbp") }}, -- GLOBAL -- + {{ calculate_safe_relative_increment("xero_booking_net_fees_in_gbp") }}, {{ calculate_safe_relative_increment("xero_operator_net_fees_in_gbp") }}, -- APIs REVENUE -- diff --git a/models/intermediate/kpis/int_kpis__agg_monthly_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__agg_monthly_invoiced_revenue.sql index 675e30c..cc962ed 100644 --- a/models/intermediate/kpis/int_kpis__agg_monthly_invoiced_revenue.sql +++ b/models/intermediate/kpis/int_kpis__agg_monthly_invoiced_revenue.sql @@ -36,6 +36,7 @@ sum( xero_old_dashboard_booking_net_fees_in_gbp ) as xero_old_dashboard_booking_net_fees_in_gbp, + sum(xero_booking_net_fees_in_gbp) as xero_booking_net_fees_in_gbp, sum(xero_listing_net_fees_in_gbp) as xero_listing_net_fees_in_gbp, sum(xero_verification_net_fees_in_gbp) as xero_verification_net_fees_in_gbp, sum(xero_operator_net_fees_in_gbp) as xero_operator_net_fees_in_gbp, diff --git a/models/intermediate/kpis/int_kpis__agg_mtd_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__agg_mtd_invoiced_revenue.sql index 09c967b..9b18211 100644 --- a/models/intermediate/kpis/int_kpis__agg_mtd_invoiced_revenue.sql +++ b/models/intermediate/kpis/int_kpis__agg_mtd_invoiced_revenue.sql @@ -36,6 +36,7 @@ sum( xero_old_dashboard_booking_net_fees_in_gbp ) as xero_old_dashboard_booking_net_fees_in_gbp, + sum(xero_booking_net_fees_in_gbp) as xero_booking_net_fees_in_gbp, sum(xero_listing_net_fees_in_gbp) as xero_listing_net_fees_in_gbp, sum(xero_verification_net_fees_in_gbp) as xero_verification_net_fees_in_gbp, sum(xero_operator_net_fees_in_gbp) as xero_operator_net_fees_in_gbp, diff --git a/models/intermediate/kpis/int_kpis__metric_daily_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__metric_daily_invoiced_revenue.sql index ea0da5a..3ed44cd 100644 --- a/models/intermediate/kpis/int_kpis__metric_daily_invoiced_revenue.sql +++ b/models/intermediate/kpis/int_kpis__metric_daily_invoiced_revenue.sql @@ -101,6 +101,26 @@ select else 0 end ) as xero_old_dashboard_booking_net_fees_in_gbp, + sum( + case + when + -- Computes total bookings fees from both Old Dash and New Dash + -- This needs to be properly handled in the aggregation logic once + -- the alignment with Finance is done. + ixsdm.accounting_root_aggregation in ( + 'Old Dashboard Booking Fees', + 'Basic Protection', + 'Protection Plus', + 'Protection Pro', + 'Basic Screening', + 'Screening Plus', + 'Id Verification', + 'Sex Offenders Check' + ) + then ixsdm.line_amount_wo_taxes_in_gbp + else 0 + end + ) as xero_booking_net_fees_in_gbp, sum( case when ixsdm.accounting_root_aggregation = 'Listing Fees' @@ -118,7 +138,6 @@ select sum( case when - -- New Dash ixsdm.accounting_kpis_aggregation = 'Invoiced Operator Revenue' -- Prior to 1st January 2023 we didn't have the split of Booking -- Fees, Listing Fees and Verification Fees. Everything is diff --git a/models/intermediate/kpis/int_kpis__metric_monthly_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__metric_monthly_invoiced_revenue.sql index be2648a..7e8e496 100644 --- a/models/intermediate/kpis/int_kpis__metric_monthly_invoiced_revenue.sql +++ b/models/intermediate/kpis/int_kpis__metric_monthly_invoiced_revenue.sql @@ -41,6 +41,7 @@ select sum( ir.xero_old_dashboard_booking_net_fees_in_gbp ) as xero_old_dashboard_booking_net_fees_in_gbp, + sum(ir.xero_booking_net_fees_in_gbp) as xero_booking_net_fees_in_gbp, sum(ir.xero_listing_net_fees_in_gbp) as xero_listing_net_fees_in_gbp, sum(ir.xero_verification_net_fees_in_gbp) as xero_verification_net_fees_in_gbp, sum(ir.xero_operator_net_fees_in_gbp) as xero_operator_net_fees_in_gbp, diff --git a/models/intermediate/kpis/int_kpis__metric_mtd_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__metric_mtd_invoiced_revenue.sql index 41058ac..9bd4558 100644 --- a/models/intermediate/kpis/int_kpis__metric_mtd_invoiced_revenue.sql +++ b/models/intermediate/kpis/int_kpis__metric_mtd_invoiced_revenue.sql @@ -41,6 +41,7 @@ select sum( ir.xero_old_dashboard_booking_net_fees_in_gbp ) as xero_old_dashboard_booking_net_fees_in_gbp, + sum(ir.xero_booking_net_fees_in_gbp) as xero_booking_net_fees_in_gbp, sum(ir.xero_listing_net_fees_in_gbp) as xero_listing_net_fees_in_gbp, sum(ir.xero_verification_net_fees_in_gbp) as xero_verification_net_fees_in_gbp, sum(ir.xero_operator_net_fees_in_gbp) as xero_operator_net_fees_in_gbp, diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index 7a6d50d..6c57e52 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -4407,6 +4407,13 @@ models: Sum of daily Old Dashboard Booking Net Fees, in GBP, without taxes in a given date and per specified dimension. + - name: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + Sum of daily Total Booking Net Fees, in GBP, without taxes + in a given date and per specified dimension. This takes into + account both Old Dashboard and New Dashboard. + - name: xero_listing_net_fees_in_gbp data_type: decimal description: | @@ -4609,6 +4616,13 @@ models: Sum of accumulated Old Dashboard Booking Net Fees, in GBP, without taxes in a given month and per specified dimension. + - name: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Total Booking Net Fees, in GBP, without taxes + in a given month and per specified dimension. This takes into + account both Old Dashboard and New Dashboard. + - name: xero_listing_net_fees_in_gbp data_type: decimal description: | @@ -4804,6 +4818,13 @@ models: Sum of accumulated Old Dashboard Booking Net Fees, in GBP, without taxes in a given month up to the given date and per specified dimension. + - name: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Total Booking Net Fees, in GBP, without taxes + in a given month up to the given date and per specified dimension. + This takes into account both Old Dashboard and New Dashboard. + - name: xero_listing_net_fees_in_gbp data_type: decimal description: | @@ -4905,6 +4926,7 @@ models: - xero_protection_pro_net_fees_in_gbp - xero_basic_screening_net_fees_in_gbp - xero_old_dashboard_booking_net_fees_in_gbp + - xero_booking_net_fees_in_gbp - xero_listing_net_fees_in_gbp - xero_verification_net_fees_in_gbp - xero_operator_net_fees_in_gbp @@ -4984,6 +5006,13 @@ models: The monthly Old Dashboard Booking Net Fees, in GBP, without taxes for a given date, dimension and value. + - name: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + The monthly Total Booking Net Fees, in GBP, without taxes + for a given date, dimension and value. + This takes into account both Old Dashboard and New Dashboard. + - name: xero_listing_net_fees_in_gbp data_type: decimal description: | @@ -5082,6 +5111,7 @@ models: - xero_protection_pro_net_fees_in_gbp - xero_basic_screening_net_fees_in_gbp - xero_old_dashboard_booking_net_fees_in_gbp + - xero_booking_net_fees_in_gbp - xero_listing_net_fees_in_gbp - xero_verification_net_fees_in_gbp - xero_operator_net_fees_in_gbp @@ -5162,6 +5192,13 @@ models: The month-to-date Old Dashboard Booking Net Fees, in GBP, without taxes for a given date, dimension and value. + - name: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + The month-to-date Total Booking Net Fees, in GBP, without taxes + for a given date, dimension and value. + This takes into account both Old Dashboard and New Dashboard. + - name: xero_listing_net_fees_in_gbp data_type: decimal description: | diff --git a/models/reporting/general/monthly_aggregated_metrics_history_by_deal.sql b/models/reporting/general/monthly_aggregated_metrics_history_by_deal.sql index 23d6929..b90e40b 100644 --- a/models/reporting/general/monthly_aggregated_metrics_history_by_deal.sql +++ b/models/reporting/general/monthly_aggregated_metrics_history_by_deal.sql @@ -98,12 +98,9 @@ select then xero_old_dashboard_booking_net_fees_in_gbp else null end as xero_old_dashboard_booking_net_fees_in_gbp, - -- Following line is a temporary handler to not break reporting. - -- We will need this line anyway for the combination of Old and New - -- Dash. case when {{ is_date_before_20th_of_previous_month("date") }} - then xero_old_dashboard_booking_net_fees_in_gbp + then xero_booking_net_fees_in_gbp else null end as xero_booking_net_fees_in_gbp, case diff --git a/tests/kpis_additive_metrics_per_dimension_are_consistent.sql b/tests/kpis_additive_metrics_per_dimension_are_consistent.sql index 8e3c7bf..19e753f 100644 --- a/tests/kpis_additive_metrics_per_dimension_are_consistent.sql +++ b/tests/kpis_additive_metrics_per_dimension_are_consistent.sql @@ -41,6 +41,7 @@ than the value reported in the Global dimension. "Invoiced APIs Revenue", "Invoiced Athena Revenue", "Invoiced Old Dashboard Booking Fees Revenue", + "Invoiced Total Booking Fees Revenue", "Invoiced E-Deposit Revenue", "Invoiced Listing Fees Revenue", "Invoiced Operator Revenue", diff --git a/tests/kpis_global_metrics_outlier_detection.sql b/tests/kpis_global_metrics_outlier_detection.sql index 4f4d667..2ee7b52 100644 --- a/tests/kpis_global_metrics_outlier_detection.sql +++ b/tests/kpis_global_metrics_outlier_detection.sql @@ -32,6 +32,7 @@ point it becomes too sensitive, just adapt the following parameters. "Invoiced APIs Revenue", "Invoiced Athena Revenue", "Invoiced Old Dashboard Booking Fees Revenue", + "Invoiced Total Booking Fees Revenue", "Invoiced E-Deposit Revenue", "Invoiced Listing Fees Revenue", "Invoiced Operator Revenue",