From f5311fa954223a62e3b9d462218e5291a3f1e75e Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Tue, 5 Nov 2024 16:57:23 +0000 Subject: [PATCH] Merged PR 3431: Adds Invoicing metrics # Description Same old story: includes all metrics coming from Xero. Adds a daily model, monthly, mtd + monthly agg and mtd agg A test to compare values new vs. old AND fixes the issue I mentioned with the timestamp - an issue in the old KPIs. # 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. - [NA] 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: #23565 --- .../intermediate/cross/int_dates_by_deal.sql | 2 +- .../cross/int_dates_mtd_by_dimension.sql | 17 +- ...int_kpis__agg_monthly_invoiced_revenue.sql | 33 ++ .../int_kpis__agg_mtd_invoiced_revenue.sql | 33 ++ ...nt_kpis__metric_daily_invoiced_revenue.sql | 99 ++++ ..._kpis__metric_monthly_invoiced_revenue.sql | 37 ++ .../int_kpis__metric_mtd_invoiced_revenue.sql | 38 ++ models/intermediate/kpis/schema.yml | 560 +++++++++++++++++- ...s_refactor_equivalent_invoiced_revenue.sql | 141 +++++ 9 files changed, 947 insertions(+), 13 deletions(-) create mode 100644 models/intermediate/kpis/int_kpis__agg_monthly_invoiced_revenue.sql create mode 100644 models/intermediate/kpis/int_kpis__agg_mtd_invoiced_revenue.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_daily_invoiced_revenue.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_monthly_invoiced_revenue.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_mtd_invoiced_revenue.sql create mode 100644 tests/tmp_kpis_refactor_equivalent_invoiced_revenue.sql diff --git a/models/intermediate/cross/int_dates_by_deal.sql b/models/intermediate/cross/int_dates_by_deal.sql index a560da2..07d1eb3 100644 --- a/models/intermediate/cross/int_dates_by_deal.sql +++ b/models/intermediate/cross/int_dates_by_deal.sql @@ -16,7 +16,7 @@ select distinct d.month_start_date as first_day_month, d.month_end_date as last_day_month from int_core__unified_user u -inner join int_dates d on d.date_day >= u.created_date_utc +inner join int_dates d on d.date_day >= date(u.created_date_utc) inner join int_core__deal deal on deal.id_deal = u.id_deal where -- include only up-to yesterday diff --git a/models/intermediate/cross/int_dates_mtd_by_dimension.sql b/models/intermediate/cross/int_dates_mtd_by_dimension.sql index a24e9aa..094005f 100644 --- a/models/intermediate/cross/int_dates_mtd_by_dimension.sql +++ b/models/intermediate/cross/int_dates_mtd_by_dimension.sql @@ -1,4 +1,3 @@ - {% set dimensions = get_kpi_dimensions() %} {{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }} @@ -7,9 +6,7 @@ with int_core__mtd_accommodation_segmentation as ( select * from {{ ref("int_core__mtd_accommodation_segmentation") }} ), - int_core__user_host as ( - select * from {{ ref("int_core__user_host") }} - ), + int_core__user_host as (select * from {{ ref("int_core__user_host") }}), int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}) {% for dimension in dimensions %} @@ -26,13 +23,13 @@ with d.is_current_month from int_dates_mtd d {% if dimension.dimension == "'by_number_of_listings'" %} - inner join int_core__mtd_accommodation_segmentation a - on d.date = a.date + inner join int_core__mtd_accommodation_segmentation a on d.date = a.date {% elif dimension.dimension == "'by_billing_country'" %} - inner join int_core__user_host h - on d.date >= h.created_date_utc - and h.main_billing_country_iso_3_per_deal is not null - {% endif %} + inner join + int_core__user_host h + on d.date >= date(h.created_date_utc) + and h.main_billing_country_iso_3_per_deal is not null + {% endif %} {% if not loop.last %} union all {% endif %} diff --git a/models/intermediate/kpis/int_kpis__agg_monthly_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__agg_monthly_invoiced_revenue.sql new file mode 100644 index 0000000..807396e --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_monthly_invoiced_revenue.sql @@ -0,0 +1,33 @@ +{% set dimensions = get_kpi_dimensions_per_model("INVOICED_REVENUE") %} + +{{ + config( + materialized="table", unique_key=["end_date", "dimension", "dimension_value"] + ) +}} + + +{% for dimension in dimensions %} + select + -- Unique Key -- + start_date, + end_date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + -- Metrics -- + 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, + sum( + xero_waiver_paid_back_to_host_in_gbp + ) as xero_waiver_paid_back_to_host_in_gbp, + sum(xero_e_deposit_net_fees_in_gbp) as xero_e_deposit_net_fees_in_gbp, + sum(xero_guesty_net_fees_in_gbp) as xero_guesty_net_fees_in_gbp, + sum(xero_apis_net_fees_in_gbp) as xero_apis_net_fees_in_gbp + from {{ ref("int_kpis__metric_monthly_invoiced_revenue") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__agg_mtd_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__agg_mtd_invoiced_revenue.sql new file mode 100644 index 0000000..72f5324 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_mtd_invoiced_revenue.sql @@ -0,0 +1,33 @@ +{% set dimensions = get_kpi_dimensions_per_model("INVOICED_REVENUE") %} + +{{ + config( + materialized="table", unique_key=["end_date", "dimension", "dimension_value"] + ) +}} + + +{% for dimension in dimensions %} + select + -- Unique Key -- + start_date, + end_date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + -- Metrics -- + 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, + sum( + xero_waiver_paid_back_to_host_in_gbp + ) as xero_waiver_paid_back_to_host_in_gbp, + sum(xero_e_deposit_net_fees_in_gbp) as xero_e_deposit_net_fees_in_gbp, + sum(xero_guesty_net_fees_in_gbp) as xero_guesty_net_fees_in_gbp, + sum(xero_apis_net_fees_in_gbp) as xero_apis_net_fees_in_gbp + from {{ ref("int_kpis__metric_mtd_invoiced_revenue") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__metric_daily_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__metric_daily_invoiced_revenue.sql new file mode 100644 index 0000000..3698185 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_daily_invoiced_revenue.sql @@ -0,0 +1,99 @@ +{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %} +{% set booking_fee_items = "('EU BOOKING FEE','ZAR BOOKINGS','BOOKING FEE - NON-UK','USD BOOKINGS','CAD BOOKINGS','BOOKING FEE - UK','AUD BOOKINGS')" %} +{% set listing_fee_items = "('USD LISTINGS','LISTING FEE - NON UK','ZAR LISTINGS','CAD LISTINGS','LISTING FEE - UK','AUD LISTINGS','EU LISTINGS')" %} +{% set waiver_items = "('DAMAGE WAVER', 'DAMAGE WAIVER')" %} +{% set verification_fee_items = "('VERIFICATION FEE')" %} +{% set e_deposit_account_name = "('E-DEPOSIT FEES')" %} +{% set guesty_account_name = "('GUESTY FEES', 'GUESTY ADMINISTRATION FEE')" %} + +{{ config(materialized="table", unique_key=["date", "id_deal"]) }} +select + -- Unique Key -- + ixsdm.document_issued_date_utc as date, + coalesce(ixsdm.id_deal, 'UNSET') as id_deal, + -- Dimensions -- + coalesce( + icd.main_billing_country_iso_3_per_deal, 'UNSET' + ) as main_billing_country_iso_3_per_deal, + coalesce( + icmas.active_accommodations_per_deal_segmentation, 'UNSET' + ) as active_accommodations_per_deal_segmentation, + -- Metrics -- + sum( + case + when upper(ixsdm.item_code) in {{ booking_fee_items }} + then ixsdm.line_amount_wo_taxes_in_gbp + else null + end + ) as xero_booking_net_fees_in_gbp, + sum( + case + when upper(ixsdm.item_code) in {{ listing_fee_items }} + then ixsdm.line_amount_wo_taxes_in_gbp + else null + end + ) as xero_listing_net_fees_in_gbp, + sum( + case + when upper(ixsdm.item_code) in {{ verification_fee_items }} + then ixsdm.line_amount_wo_taxes_in_gbp + else null + end + ) as xero_verification_net_fees_in_gbp, + sum( + case + when + upper(ixsdm.item_code) in {{ booking_fee_items }} + or upper(ixsdm.item_code) in {{ listing_fee_items }} + or upper(ixsdm.item_code) in {{ verification_fee_items }} + then ixsdm.line_amount_wo_taxes_in_gbp + else null + end + ) as xero_operator_net_fees_in_gbp, + sum( + case + when upper(ixsdm.item_code) in {{ waiver_items }} + then ixsdm.line_amount_wo_taxes_in_gbp + else null + end + ) as xero_waiver_paid_back_to_host_in_gbp, + sum( + case + when upper(ixsdm.account_name) in {{ e_deposit_account_name }} + then ixsdm.line_amount_wo_taxes_in_gbp + else null + end + ) as xero_e_deposit_net_fees_in_gbp, + sum( + case + when upper(ixsdm.account_name) in {{ guesty_account_name }} + then ixsdm.line_amount_wo_taxes_in_gbp + else null + end + ) as xero_guesty_net_fees_in_gbp, + sum( + case + when + upper(ixsdm.account_name) in {{ e_deposit_account_name }} + or upper(ixsdm.account_name) in {{ guesty_account_name }} + then ixsdm.line_amount_wo_taxes_in_gbp + else null + end + ) as xero_apis_net_fees_in_gbp +from {{ ref("int_xero__sales_denom_mart") }} as ixsdm +left join {{ ref("int_core__deal") }} as icd on ixsdm.id_deal = icd.id_deal +left join + {{ ref("int_kpis__dimension_daily_accommodation") }} as icmas + on ixsdm.id_deal = icmas.id_deal + and ixsdm.document_issued_date_utc = icmas.date +where + upper(ixsdm.document_status) in {{ relevant_document_statuses }} + and ( + upper(ixsdm.item_code) in {{ booking_fee_items }} + or upper(ixsdm.item_code) in {{ listing_fee_items }} + or upper(ixsdm.item_code) in {{ verification_fee_items }} + or upper(ixsdm.item_code) in {{ waiver_items }} + or upper(ixsdm.account_name) in {{ e_deposit_account_name }} + or upper(ixsdm.account_name) in {{ guesty_account_name }} + ) +group by 1, 2, 3, 4 diff --git a/models/intermediate/kpis/int_kpis__metric_monthly_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__metric_monthly_invoiced_revenue.sql new file mode 100644 index 0000000..696b05e --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_monthly_invoiced_revenue.sql @@ -0,0 +1,37 @@ +{{ + config( + materialized="view", + unique_key=[ + "end_date", + "id_deal", + "active_accommodations_per_deal_segmentation", + ], + ) +}} + +select + -- Unique Key -- + d.first_day_month as start_date, + d.date as end_date, + ir.id_deal, + ir.active_accommodations_per_deal_segmentation, + -- Dimensions -- + ir.main_billing_country_iso_3_per_deal, + -- Metrics -- + 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, + sum( + ir.xero_waiver_paid_back_to_host_in_gbp + ) as xero_waiver_paid_back_to_host_in_gbp, + sum(ir.xero_e_deposit_net_fees_in_gbp) as xero_e_deposit_net_fees_in_gbp, + sum(ir.xero_guesty_net_fees_in_gbp) as xero_guesty_net_fees_in_gbp, + sum(ir.xero_apis_net_fees_in_gbp) as xero_apis_net_fees_in_gbp + +from {{ ref("int_kpis__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_invoiced_revenue") }} ir + on date_trunc('month', ir.date)::date = d.first_day_month +where d.is_end_of_month = true and ir.id_deal is not null +group by 1, 2, 3, 4, 5 diff --git a/models/intermediate/kpis/int_kpis__metric_mtd_invoiced_revenue.sql b/models/intermediate/kpis/int_kpis__metric_mtd_invoiced_revenue.sql new file mode 100644 index 0000000..fa69fff --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_mtd_invoiced_revenue.sql @@ -0,0 +1,38 @@ +{{ + config( + materialized="view", + unique_key=[ + "end_date", + "id_deal", + "active_accommodations_per_deal_segmentation", + ], + ) +}} + +select + -- Unique Key -- + d.first_day_month as start_date, + d.date as end_date, + ir.id_deal, + ir.active_accommodations_per_deal_segmentation, + -- Dimensions -- + ir.main_billing_country_iso_3_per_deal, + -- Metrics -- + 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, + sum( + ir.xero_waiver_paid_back_to_host_in_gbp + ) as xero_waiver_paid_back_to_host_in_gbp, + sum(ir.xero_e_deposit_net_fees_in_gbp) as xero_e_deposit_net_fees_in_gbp, + sum(ir.xero_guesty_net_fees_in_gbp) as xero_guesty_net_fees_in_gbp, + sum(ir.xero_apis_net_fees_in_gbp) as xero_apis_net_fees_in_gbp + +from {{ ref("int_kpis__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_invoiced_revenue") }} ir + on date_trunc('month', ir.date)::date = d.first_day_month + and extract(day from ir.date) <= d.day +where d.is_month_to_date = true and ir.id_deal is not null +group by 1, 2, 3, 4, 5 diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index 9241c55..65e419e 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -3233,7 +3233,7 @@ models: data_type: bigint description: | Average daily CSAT score in a given date and per specified dimension. - + - name: int_kpis__metric_monthly_check_in_attributed_guest_journeys description: | This model computes the Monthly metrics associated with Guest Journeys @@ -3769,7 +3769,7 @@ models: Month-to-date aggregated count of guest journeys completed for a given date, dimension, and value. tests: - - not_null + - not_null - name: count_csat_score data_type: numeric @@ -4125,3 +4125,559 @@ models: description: | The month-to-date Host Resolution Amount Paid, in GBP, for a given date, dimension and value. + + - name: int_kpis__metric_daily_invoiced_revenue + description: | + This model computes the Daily Invoiced Revenue at the deepest granularity. + + The unique key corresponds to the deepest granularity of the model, + in this case: + - date, + - id_deal. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - id_deal + + columns: + - name: date + data_type: date + description: Date of when the document was issued. + tests: + - not_null + + - name: id_deal + data_type: string + description: Unique identifier of an account. + tests: + - not_null + + - name: active_accommodations_per_deal_segmentation + data_type: string + description: | + Segment value based on the number of listings booked in 12 months + for a given deal and date. + tests: + - not_null + - accepted_values: + values: + - "0" + - "01-05" + - "06-20" + - "21-60" + - "61+" + - "UNSET" + + - 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: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + Sum of daily Booking Net Fees, in GBP, without taxes + in a given date and per specified dimension. + + - name: xero_listing_net_fees_in_gbp + data_type: decimal + description: | + Sum of daily Listing Net Fees, in GBP, without taxes + in a given date and per specified dimension. + + - name: xero_verification_net_fees_in_gbp + data_type: decimal + description: | + Sum of daily Verification Net Fees, in GBP, without taxes + in a given date and per specified dimension. + + - name: xero_operator_net_fees_in_gbp + data_type: decimal + description: | + Sum of daily Operator Net Fees, which include Booking, + Listing and Verification Net Fees, in GBP, without taxes + in a given date and per specified dimension. + + - name: xero_e_deposit_net_fees_in_gbp + data_type: decimal + description: | + Sum of daily E-Deposit Net Fees, in GBP, without taxes + in a given date and per specified dimension. + + - name: xero_guesty_net_fees_in_gbp + data_type: decimal + description: | + Sum of daily Athena (Guesty) Net Fees, in GBP, without taxes + in a given date and per specified dimension. + + - name: xero_apis_net_fees_in_gbp + data_type: decimal + description: | + Sum of daily API Net Fees, which include E-Deposit, + and Athena (Guesty) Net Fees, in GBP, without taxes + in a given date and per specified dimension. + + - name: xero_waiver_paid_back_to_host_in_gbp + data_type: decimal + description: | + Sum of daily Waiver Amount Paid Back to Hosts, in GBP, + without taxes in a given date and per specified dimension. + + - name: int_kpis__metric_monthly_invoiced_revenue + description: | + This model computes the Monthly Invoiced Revenue at the + deepest granularity. + Be aware that any dimension that can change over the monthly period, + such as daily segmentations, are included in the primary key of the + model. + + The unique key corresponds to: + - end_date, + - id_deal, + - active_accommodations_per_deal_segmentation. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - end_date + - id_deal + - active_accommodations_per_deal_segmentation + + columns: + - name: start_date + data_type: date + description: | + The start date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: end_date + data_type: date + description: | + The end date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: id_deal + data_type: string + description: Unique identifier of an account. + tests: + - not_null + + - name: active_accommodations_per_deal_segmentation + data_type: string + description: | + Segment value based on the number of listings booked in 12 months + for a given deal and date. + tests: + - not_null + - accepted_values: + values: + - "0" + - "01-05" + - "06-20" + - "21-60" + - "61+" + - "UNSET" + + - 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: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Booking Net Fees, in GBP, without taxes + in a given month and per specified dimension. + + - name: xero_listing_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Listing Net Fees, in GBP, without taxes + in a given month and per specified dimension. + + - name: xero_verification_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Verification Net Fees, in GBP, without taxes + in a given month and per specified dimension. + + - name: xero_operator_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Operator Net Fees, which include Booking, + Listing and Verification Net Fees, in GBP, without taxes + in a given month and per specified dimension. + + - name: xero_e_deposit_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated E-Deposit Net Fees, in GBP, without taxes + in a given month and per specified dimension. + + - name: xero_guesty_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Athena (Guesty) Net Fees, in GBP, without taxes + in a given month and per specified dimension. + + - name: xero_apis_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated API Net Fees, which include E-Deposit, + and Athena (Guesty) Net Fees, in GBP, without taxes + in a given month and per specified dimension. + + - name: xero_waiver_paid_back_to_host_in_gbp + data_type: decimal + description: | + Sum of accumulated Waiver Amount Paid Back to Hosts, in GBP, + without taxes in a given month and per specified dimension. + + - name: int_kpis__metric_mtd_invoiced_revenue + description: | + This model computes the Month-To-Date Invoiced Revenue at the + deepest granularity. + Be aware that any dimension that can change over the monthly period, + such as daily segmentations, are included in the primary key of the + model. + + The unique key corresponds to: + - end_date, + - id_deal, + - active_accommodations_per_deal_segmentation. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - end_date + - id_deal + - active_accommodations_per_deal_segmentation + + columns: + - name: start_date + data_type: date + description: | + The start date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: end_date + data_type: date + description: | + The end date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: id_deal + data_type: string + description: Unique identifier of an account. + tests: + - not_null + + - name: active_accommodations_per_deal_segmentation + data_type: string + description: | + Segment value based on the number of listings booked in 12 months + for a given deal and date. + tests: + - not_null + - accepted_values: + values: + - "0" + - "01-05" + - "06-20" + - "21-60" + - "61+" + - "UNSET" + + - 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: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Booking Net Fees, in GBP, without taxes + in a given month up to the given date and per specified dimension. + + - name: xero_listing_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Listing Net Fees, in GBP, without taxes + in a given month up to the given date and per specified dimension. + + - name: xero_verification_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Verification Net Fees, in GBP, without taxes + in a given month up to the given date and per specified dimension. + + - name: xero_operator_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Operator Net Fees, which include Booking, + Listing and Verification Net Fees, in GBP, without taxes + in a given month up to the given date and per specified dimension. + + - name: xero_e_deposit_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated E-Deposit Net Fees, in GBP, without taxes + in a given month up to the given date and per specified dimension. + + - name: xero_guesty_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated Athena (Guesty) Net Fees, in GBP, without taxes + in a given month up to the given date and per specified dimension. + + - name: xero_apis_net_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated API Net Fees, which include E-Deposit, + and Athena (Guesty) Net Fees, in GBP, without taxes + in a given month up to the given date and per specified dimension. + + - name: xero_waiver_paid_back_to_host_in_gbp + data_type: decimal + description: | + Sum of accumulated Waiver Amount Paid Back to Hosts, in GBP, without taxes + in a given month up to the given date and per specified dimension. + + - name: int_kpis__agg_monthly_invoiced_revenue + description: | + This model computes the dimension aggregation for + Monthly Invoiced Revenue. + + The primary key of this model is end_date, dimension + and dimension_value. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - end_date + - dimension + - dimension_value + + columns: + - name: start_date + data_type: date + description: | + The start date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: end_date + data_type: date + description: | + The end date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: dimension + data_type: string + description: The dimension or granularity of the metrics. + tests: + - assert_dimension_completeness: + metric_column_name: xero_booking_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_listing_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_verification_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_operator_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_e_deposit_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_guesty_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_apis_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_waiver_paid_back_to_host_in_gbp + - accepted_values: + values: + - global + - by_number_of_listings + - by_billing_country + - by_deal + + - name: dimension_value + data_type: string + description: The value or segment available for the selected dimension. + tests: + - not_null + + - name: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + The monthly Booking Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_listing_net_fees_in_gbp + data_type: decimal + description: | + The monthly Listing Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_verification_net_fees_in_gbp + data_type: decimal + description: | + The monthly Verification Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_operator_net_fees_in_gbp + data_type: decimal + description: | + The monthly Operator Net Fees, which include Booking, + Listing and Verification Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_e_deposit_net_fees_in_gbp + data_type: decimal + description: | + The monthly E-Deposit Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_guesty_net_fees_in_gbp + data_type: decimal + description: | + The monthly Athena (Guesty) Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_apis_net_fees_in_gbp + data_type: decimal + description: | + The monthly API Net Fees, which include E-Deposit, + and Athena (Guesty) Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_waiver_paid_back_to_host_in_gbp + data_type: decimal + description: | + The monthly Waiver Amount Paid Back to Hosts, in GBP, without taxes + for a given date, dimension and value. + + - name: int_kpis__agg_mtd_invoiced_revenue + description: | + This model computes the dimension aggregation for + Month-To-Date Invoiced Revenue. + + The primary key of this model is end_date, dimension + and dimension_value. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - end_date + - dimension + - dimension_value + + columns: + - name: start_date + data_type: date + description: | + The start date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: end_date + data_type: date + description: | + The end date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: dimension + data_type: string + description: The dimension or granularity of the metrics. + tests: + - assert_dimension_completeness: + metric_column_name: xero_booking_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_listing_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_verification_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_operator_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_e_deposit_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_guesty_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_apis_net_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: xero_waiver_paid_back_to_host_in_gbp + + - accepted_values: + values: + - global + - by_number_of_listings + - by_billing_country + - by_deal + + - name: dimension_value + data_type: string + description: The value or segment available for the selected dimension. + tests: + - not_null + + - name: xero_booking_net_fees_in_gbp + data_type: decimal + description: | + The month-to-date Booking Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_listing_net_fees_in_gbp + data_type: decimal + description: | + The month-to-date Listing Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_verification_net_fees_in_gbp + data_type: decimal + description: | + The month-to-date Verification Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_operator_net_fees_in_gbp + data_type: decimal + description: | + The month-to-date Operator Net Fees, which include Booking, + Listing and Verification Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_e_deposit_net_fees_in_gbp + data_type: decimal + description: | + The month-to-date E-Deposit Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_guesty_net_fees_in_gbp + data_type: decimal + description: | + The month-to-date Athena (Guesty) Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_apis_net_fees_in_gbp + data_type: decimal + description: | + The month-to-date API Net Fees, which include E-Deposit, + and Athena (Guesty) Net Fees, in GBP, without taxes + for a given date, dimension and value. + + - name: xero_waiver_paid_back_to_host_in_gbp + data_type: decimal + description: | + The month-to-date Waiver Amount Paid Back to Hosts, in GBP, + without taxes for a given date, dimension and value. diff --git a/tests/tmp_kpis_refactor_equivalent_invoiced_revenue.sql b/tests/tmp_kpis_refactor_equivalent_invoiced_revenue.sql new file mode 100644 index 0000000..d948b4d --- /dev/null +++ b/tests/tmp_kpis_refactor_equivalent_invoiced_revenue.sql @@ -0,0 +1,141 @@ +{% set min_date = "2022-01-01" %} +{% set dimensions = ("global", "by_billing_country") %} +-- "by_number_of_listings" excluded on purpose - there's differences because of daily +-- segmentation +with + new_mtd_invoiced_revenue as ( + select + end_date as date, + dimension, + dimension_value, + xero_booking_net_fees_in_gbp, + xero_listing_net_fees_in_gbp, + xero_verification_net_fees_in_gbp, + xero_operator_net_fees_in_gbp, + xero_waiver_paid_back_to_host_in_gbp, + xero_e_deposit_net_fees_in_gbp, + xero_guesty_net_fees_in_gbp, + xero_apis_net_fees_in_gbp + from {{ ref("int_kpis__agg_mtd_invoiced_revenue") }} + where + end_date >= '{{ min_date }}' + and dimension in {{ dimensions }} + and dimension_value <> 'UNSET' + ), + new_monthly_invoiced_revenue as ( + select + end_date as date, + dimension, + dimension_value, + xero_booking_net_fees_in_gbp, + xero_listing_net_fees_in_gbp, + xero_verification_net_fees_in_gbp, + xero_operator_net_fees_in_gbp, + xero_waiver_paid_back_to_host_in_gbp, + xero_e_deposit_net_fees_in_gbp, + xero_guesty_net_fees_in_gbp, + xero_apis_net_fees_in_gbp + from {{ ref("int_kpis__agg_monthly_invoiced_revenue") }} + where + end_date >= '{{ min_date }}' + and dimension in {{ dimensions }} + and dimension_value <> 'UNSET' + ), + new_invoiced_revenue as ( + select * + from new_mtd_invoiced_revenue + union all + select * + from new_monthly_invoiced_revenue + ), + old_invoiced_revenue as ( + select + date, + dimension, + dimension_value, + xero_booking_net_fees_in_gbp, + xero_listing_net_fees_in_gbp, + xero_verification_net_fees_in_gbp, + xero_operator_net_fees_in_gbp, + xero_waiver_paid_back_to_host_in_gbp, + xero_e_deposit_net_fees_in_gbp, + xero_guesty_net_fees_in_gbp, + xero_apis_net_fees_in_gbp + from {{ ref("int_xero__mtd_invoicing_metrics") }} + where date >= '{{ min_date }}' and dimension in {{ dimensions }} + ), + comparison as ( + select + coalesce(o.date, n.date) as date, + coalesce(o.dimension, n.dimension) as dimension, + coalesce(o.dimension_value, n.dimension_value) as dimension_value, + o.xero_booking_net_fees_in_gbp as old_xero_booking_net_fees_in_gbp, + n.xero_booking_net_fees_in_gbp as new_xero_booking_net_fees_in_gbp, + coalesce(o.xero_booking_net_fees_in_gbp, 0) - coalesce( + n.xero_booking_net_fees_in_gbp, 0 + ) as diff_xero_booking_net_fees_in_gbp, + + o.xero_listing_net_fees_in_gbp as old_xero_listing_net_fees_in_gbp, + n.xero_listing_net_fees_in_gbp as new_xero_listing_net_fees_in_gbp, + coalesce(o.xero_listing_net_fees_in_gbp, 0) - coalesce( + n.xero_listing_net_fees_in_gbp, 0 + ) as diff_xero_listing_net_fees_in_gbp, + + o.xero_verification_net_fees_in_gbp + as old_xero_verification_net_fees_in_gbp, + n.xero_verification_net_fees_in_gbp + as new_xero_verification_net_fees_in_gbp, + coalesce(o.xero_verification_net_fees_in_gbp, 0) - coalesce( + n.xero_verification_net_fees_in_gbp, 0 + ) as diff_xero_verification_net_fees_in_gbp, + + o.xero_operator_net_fees_in_gbp as old_xero_operator_net_fees_in_gbp, + n.xero_operator_net_fees_in_gbp as new_xero_operator_net_fees_in_gbp, + coalesce(o.xero_operator_net_fees_in_gbp, 0) - coalesce( + n.xero_operator_net_fees_in_gbp, 0 + ) as diff_xero_operator_net_fees_in_gbp, + + o.xero_waiver_paid_back_to_host_in_gbp + as old_xero_waiver_paid_back_to_host_in_gbp, + n.xero_waiver_paid_back_to_host_in_gbp + as new_xero_waiver_paid_back_to_host_in_gbp, + coalesce(o.xero_waiver_paid_back_to_host_in_gbp, 0) - coalesce( + n.xero_waiver_paid_back_to_host_in_gbp, 0 + ) as diff_xero_waiver_paid_back_to_host_in_gbp, + + o.xero_e_deposit_net_fees_in_gbp as old_xero_e_deposit_net_fees_in_gbp, + n.xero_e_deposit_net_fees_in_gbp as new_xero_e_deposit_net_fees_in_gbp, + coalesce(o.xero_e_deposit_net_fees_in_gbp, 0) - coalesce( + n.xero_e_deposit_net_fees_in_gbp, 0 + ) as diff_xero_e_deposit_net_fees_in_gbp, + + o.xero_guesty_net_fees_in_gbp as old_xero_guesty_net_fees_in_gbp, + n.xero_guesty_net_fees_in_gbp as new_xero_guesty_net_fees_in_gbp, + coalesce(o.xero_guesty_net_fees_in_gbp, 0) - coalesce( + n.xero_guesty_net_fees_in_gbp, 0 + ) as diff_xero_guesty_net_fees_in_gbp, + + o.xero_apis_net_fees_in_gbp as old_xero_apis_net_fees_in_gbp, + n.xero_apis_net_fees_in_gbp as new_xero_apis_net_fees_in_gbp, + coalesce(o.xero_apis_net_fees_in_gbp, 0) + - coalesce(n.xero_apis_net_fees_in_gbp, 0) as diff_xero_apis_net_fees_in_gbp + + from old_invoiced_revenue o + full outer join + new_invoiced_revenue n + on o.date = n.date + and o.dimension = n.dimension + and o.dimension_value = n.dimension_value + ) +select * +from comparison +where + diff_xero_apis_net_fees_in_gbp <> 0 + or diff_xero_guesty_net_fees_in_gbp <> 0 + or diff_xero_e_deposit_net_fees_in_gbp <> 0 + or diff_xero_waiver_paid_back_to_host_in_gbp <> 0 + or diff_xero_operator_net_fees_in_gbp <> 0 + or diff_xero_verification_net_fees_in_gbp <> 0 + or diff_xero_listing_net_fees_in_gbp <> 0 + or diff_xero_booking_net_fees_in_gbp <> 0 +order by date desc