From 3ecbcb2c49ad1c7f2d9de91fa33bb57fb233c5c4 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Thu, 31 Oct 2024 09:03:15 +0000 Subject: [PATCH] Merged PR 3387: Adds Guest Payments metrics # Description Adds Guest Payments metrics, namely: * deposit_fees_in_gbp * waiver_payments_in_gbp * checkin_cover_fees_in_gbp * total_guest_payments_in_gbp It includes: * Daily model * Monthly/MTD without dimension aggregates * Monthly/MTD with dimension aggregates * Schema entries for the abovementioned 5 models * Temporary test to compare the different metrics against current production 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: #23453 --- ...pis__aggregated_monthly_guest_payments.sql | 27 ++ ...nt_kpis__aggregated_mtd_guest_payments.sql | 27 ++ .../int_kpis__metric_daily_guest_payments.sql | 71 +++ ...nt_kpis__metric_monthly_guest_payments.sql | 30 ++ .../int_kpis__metric_mtd_guest_payments.sql | 31 ++ models/intermediate/kpis/schema.yml | 429 +++++++++++++++++- ...pis_refactor_equivalent_guest_payments.sql | 92 ++++ 7 files changed, 697 insertions(+), 10 deletions(-) create mode 100644 models/intermediate/kpis/int_kpis__aggregated_monthly_guest_payments.sql create mode 100644 models/intermediate/kpis/int_kpis__aggregated_mtd_guest_payments.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_daily_guest_payments.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_monthly_guest_payments.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_mtd_guest_payments.sql create mode 100644 tests/tmp_kpis_refactor_equivalent_guest_payments.sql diff --git a/models/intermediate/kpis/int_kpis__aggregated_monthly_guest_payments.sql b/models/intermediate/kpis/int_kpis__aggregated_monthly_guest_payments.sql new file mode 100644 index 0000000..431ecb5 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__aggregated_monthly_guest_payments.sql @@ -0,0 +1,27 @@ +{% set dimensions = get_kpi_dimensions_per_model("GUEST_PAYMENTS") %} + +{{ + 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(deposit_fees_in_gbp) as deposit_fees_in_gbp, + sum(waiver_payments_in_gbp) as waiver_payments_in_gbp, + sum(checkin_cover_fees_in_gbp) as checkin_cover_fees_in_gbp, + sum(total_guest_payments_in_gbp) as total_guest_payments_in_gbp + from {{ ref("int_kpis__metric_monthly_guest_payments") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__aggregated_mtd_guest_payments.sql b/models/intermediate/kpis/int_kpis__aggregated_mtd_guest_payments.sql new file mode 100644 index 0000000..c5684e4 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__aggregated_mtd_guest_payments.sql @@ -0,0 +1,27 @@ +{% set dimensions = get_kpi_dimensions_per_model("GUEST_PAYMENTS") %} + +{{ + 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(deposit_fees_in_gbp) as deposit_fees_in_gbp, + sum(waiver_payments_in_gbp) as waiver_payments_in_gbp, + sum(checkin_cover_fees_in_gbp) as checkin_cover_fees_in_gbp, + sum(total_guest_payments_in_gbp) as total_guest_payments_in_gbp + from {{ ref("int_kpis__metric_mtd_guest_payments") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__metric_daily_guest_payments.sql b/models/intermediate/kpis/int_kpis__metric_daily_guest_payments.sql new file mode 100644 index 0000000..897780a --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_daily_guest_payments.sql @@ -0,0 +1,71 @@ +{% 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')" %} + +{{ config(materialized="table", unique_key=["date", "id_deal"]) }} + +select + -- Unique Key -- + icvp.payment_paid_date_utc as date, + coalesce(icuh.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(icvp.verification_payment_type) + in {{ deposit_fees_verification_payment_type_items }} + then icvp.amount_without_taxes_in_gbp + else null + end + ) as deposit_fees_in_gbp, + sum( + case + when + upper(icvp.verification_payment_type) + in {{ waiver_fees_verification_payment_type_items }} + then icvp.amount_without_taxes_in_gbp + else null + end + ) as waiver_payments_in_gbp, + sum( + case + when + upper(icvp.verification_payment_type) + in {{ checkin_cover_fees_verification_payment_type_items }} + then icvp.amount_without_taxes_in_gbp + else null + end + ) as checkin_cover_fees_in_gbp, + sum( + case + when + upper(icvp.verification_payment_type) + in {{ checkin_cover_fees_verification_payment_type_items }} + or upper(icvp.verification_payment_type) + in {{ waiver_fees_verification_payment_type_items }} + or upper(icvp.verification_payment_type) + in {{ deposit_fees_verification_payment_type_items }} + then icvp.amount_without_taxes_in_gbp + else null + end + ) as total_guest_payments_in_gbp +from {{ ref("int_core__verification_payments", version=2) }} as icvp +left join + {{ ref("int_core__verification_requests") }} as icvr + on icvp.id_verification_request = icvr.id_verification_request +left join + {{ ref("int_core__user_host") }} as icuh on icvr.id_user_host = icuh.id_user_host +left join {{ ref("int_core__deal") }} as icd on icuh.id_deal = icd.id_deal +left join + {{ ref("int_kpis__dimension_daily_accommodation") }} as icmas + on icuh.id_deal = icmas.id_deal + and icvp.payment_paid_date_utc = icmas.date +where upper(icvp.payment_status) = {{ var("paid_payment_state") }} +group by 1, 2, 3, 4 diff --git a/models/intermediate/kpis/int_kpis__metric_monthly_guest_payments.sql b/models/intermediate/kpis/int_kpis__metric_monthly_guest_payments.sql new file mode 100644 index 0000000..8f8e202 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_monthly_guest_payments.sql @@ -0,0 +1,30 @@ +{{ + 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, + gp.id_deal, + gp.active_accommodations_per_deal_segmentation, + -- Dimensions -- + gp.main_billing_country_iso_3_per_deal, + -- Metrics -- + 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__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_guest_payments") }} gp + on date_trunc('month', gp.date)::date = d.first_day_month +where d.is_end_of_month = true and gp.id_deal is not null +group by 1, 2, 3, 4, 5 diff --git a/models/intermediate/kpis/int_kpis__metric_mtd_guest_payments.sql b/models/intermediate/kpis/int_kpis__metric_mtd_guest_payments.sql new file mode 100644 index 0000000..8c6ecf7 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_mtd_guest_payments.sql @@ -0,0 +1,31 @@ +{{ + 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, + gp.id_deal, + gp.active_accommodations_per_deal_segmentation, + -- Dimensions -- + gp.main_billing_country_iso_3_per_deal, + -- Metrics -- + 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__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_guest_payments") }} gp + on date_trunc('month', gp.date)::date = d.first_day_month + and extract(day from gp.date) <= d.day +where d.is_month_to_date = true and gp.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 3195c39..b1d6d79 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -360,7 +360,7 @@ models: - name: created_bookings data_type: bigint description: | - Count of accummulated bookings created in a given month + Count of accumulated bookings created in a given month and per specified dimension. - name: int_kpis__metric_mtd_created_bookings @@ -442,7 +442,7 @@ models: - name: created_bookings data_type: bigint description: | - Count of accummulated bookings created in a given month up to the + Count of accumulated bookings created in a given month up to the given date and per specified dimension. - name: int_kpis__aggregated_monthly_created_bookings @@ -676,7 +676,7 @@ models: - name: created_guest_journeys data_type: bigint description: | - Count of accummulated guest journeys created in a given month + Count of accumulated guest journeys created in a given month and per specified dimension. - name: int_kpis__metric_mtd_created_guest_journeys @@ -746,7 +746,7 @@ models: - name: created_guest_journeys data_type: bigint description: | - Count of accummulated guest journeys created in a given month up to the + Count of accumulated guest journeys created in a given month up to the given date and per specified dimension. - name: int_kpis__aggregated_monthly_created_guest_journeys @@ -978,7 +978,7 @@ models: - name: started_guest_journeys data_type: bigint description: | - Count of accummulated guest journeys started in a given month + Count of accumulated guest journeys started in a given month and per specified dimension. - name: int_kpis__metric_mtd_started_guest_journeys @@ -1048,7 +1048,7 @@ models: - name: started_guest_journeys data_type: bigint description: | - Count of accummulated guest journeys started in a given month up to the + Count of accumulated guest journeys started in a given month up to the given date and per specified dimension. - name: int_kpis__aggregated_monthly_started_guest_journeys @@ -1280,7 +1280,7 @@ models: - name: completed_guest_journeys data_type: bigint description: | - Count of accummulated guest journeys completed in a given month + Count of accumulated guest journeys completed in a given month and per specified dimension. - name: int_kpis__metric_mtd_completed_guest_journeys @@ -1350,7 +1350,7 @@ models: - name: completed_guest_journeys data_type: bigint description: | - Count of accummulated guest journeys completed in a given month up to the + Count of accumulated guest journeys completed in a given month up to the given date and per specified dimension. - name: int_kpis__aggregated_monthly_completed_guest_journeys @@ -1582,7 +1582,7 @@ models: - name: guest_journeys_with_payment data_type: bigint description: | - Count of accummulated guest journeys completed in a given month + Count of accumulated guest journeys completed in a given month and per specified dimension. - name: int_kpis__metric_mtd_guest_journeys_with_payment @@ -1652,7 +1652,7 @@ models: - name: guest_journeys_with_payment data_type: bigint description: | - Count of accummulated guest journeys completed in a given month up to the + Count of accumulated guest journeys completed in a given month up to the given date and per specified dimension. - name: int_kpis__aggregated_monthly_guest_journeys_with_payment @@ -1760,3 +1760,412 @@ models: - name: guest_journeys_with_payment data_type: bigint description: The month-to-date guest journeys with payment for a given date, dimension and value. + + - name: int_kpis__metric_daily_guest_payments + description: | + This model computes the Daily Guest Payments 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 Guest Journeys have been completed. + 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: deposit_fees_in_gbp + data_type: decimal + description: | + Sum of deposit fees paid by guests, without taxes, in GBP + in a given date and per specified dimension. + + - name: waiver_payments_in_gbp + data_type: decimal + description: | + Sum of waiver payments paid by guests, without taxes, in GBP + in a given date and per specified dimension. + + - name: checkin_cover_fees_in_gbp + data_type: decimal + description: | + Sum of checkin cover fees paid by guests, without taxes, in GBP + in a given date and per specified dimension. + + - name: total_guest_payments_in_gbp + data_type: decimal + description: | + Sum of total payments paid by guests, without taxes, in GBP + in a given date and per specified dimension. + + - name: int_kpis__metric_monthly_guest_payments + description: | + This model computes the Monthly Guest Payments 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: deposit_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated deposit fees paid by guests, without taxes, + in GBP in a given month and per specified dimension. + + - name: waiver_payments_in_gbp + data_type: decimal + description: | + Sum of accumulated waiver payments paid by guests, without taxes, + in GBP in a given month and per specified dimension. + + - name: checkin_cover_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated checkin cover fees by guests, without taxes, + in GBP in a given month and per specified dimension. + + - name: total_guest_payments_in_gbp + data_type: decimal + description: | + Sum of accumulated total payments paid by guests, without taxes, + in GBP in a given month and per specified dimension. + + - name: int_kpis__metric_mtd_guest_payments + description: | + This model computes the Month-To-Date Guest Payments 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: deposit_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated deposit fees paid by guests, without taxes, + in GBP in a given month up to the given date and per specified dimension. + + - name: waiver_payments_in_gbp + data_type: decimal + description: | + Sum of accumulated waiver payments paid by guests, without taxes, + in GBP in a given month up to the given date and per specified dimension. + + - name: checkin_cover_fees_in_gbp + data_type: decimal + description: | + Sum of accumulated checkin cover fees by guests, without taxes, + in GBP in a given month up to the given date and per specified dimension. + + - name: total_guest_payments_in_gbp + data_type: decimal + description: | + Sum of accumulated total payments paid by guests, without taxes, + in GBP in a given month up to the given date and per specified dimension. + + - name: int_kpis__aggregated_monthly_guest_payments + description: | + This model computes the dimension aggregation for + Monthly Guest Payments. + + 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: deposit_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: waiver_payments_in_gbp + - assert_dimension_completeness: + metric_column_name: checkin_cover_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: total_guest_payments_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: deposit_fees_in_gbp + data_type: decimal + description: | + The monthly deposit fees paid by guests, without taxes, in GBP + for a given range date, dimension and value. + + - name: waiver_payments_in_gbp + data_type: decimal + description: | + The monthly waiver payments paid by guests, without taxes, in GBP + for a given range date, dimension and value. + + - name: checkin_cover_fees_in_gbp + data_type: decimal + description: | + The monthly checkin cover fees paid by guests, without taxes, in GBP + for a given range date, dimension and value. + + - name: total_guest_payments_in_gbp + data_type: decimal + description: | + The monthly total payments paid by guests, without taxes, in GBP + for a given range date, dimension and value. + + - name: int_kpis__aggregated_mtd_guest_payments + description: | + This model computes the dimension aggregation for + Month-To-Date Guest Payments. + + 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: deposit_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: waiver_payments_in_gbp + - assert_dimension_completeness: + metric_column_name: checkin_cover_fees_in_gbp + - assert_dimension_completeness: + metric_column_name: total_guest_payments_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: deposit_fees_in_gbp + data_type: decimal + description: | + The month-to-date deposit fees paid by guests, without taxes, in GBP + for a given range date, dimension and value. + + - name: waiver_payments_in_gbp + data_type: decimal + description: | + The month-to-date waiver payments paid by guests, without taxes, in GBP + for a given range date, dimension and value. + + - name: checkin_cover_fees_in_gbp + data_type: decimal + description: | + The month-to-date checkin cover fees paid by guests, without taxes, in GBP + for a given range date, dimension and value. + + - name: total_guest_payments_in_gbp + data_type: decimal + description: | + The month-to-date total payments paid by guests, without taxes, in GBP + for a given range date, dimension and value. diff --git a/tests/tmp_kpis_refactor_equivalent_guest_payments.sql b/tests/tmp_kpis_refactor_equivalent_guest_payments.sql new file mode 100644 index 0000000..9998f1c --- /dev/null +++ b/tests/tmp_kpis_refactor_equivalent_guest_payments.sql @@ -0,0 +1,92 @@ +{% 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_guest_payments as ( + select + end_date as date, + dimension, + dimension_value, + deposit_fees_in_gbp, + waiver_payments_in_gbp, + checkin_cover_fees_in_gbp, + total_guest_payments_in_gbp + from {{ ref("int_kpis__aggregated_mtd_guest_payments") }} + where + end_date >= '{{ min_date }}' + and dimension in {{ dimensions }} + and dimension_value <> 'UNSET' + ), + new_monthly_guest_payments as ( + select + end_date as date, + dimension, + dimension_value, + deposit_fees_in_gbp, + waiver_payments_in_gbp, + checkin_cover_fees_in_gbp, + total_guest_payments_in_gbp + from {{ ref("int_kpis__aggregated_monthly_guest_payments") }} + where + end_date >= '{{ min_date }}' + and dimension in {{ dimensions }} + and dimension_value <> 'UNSET' + ), + new_guest_payments as ( + select * + from new_mtd_guest_payments + union all + select * + from new_monthly_guest_payments + ), + old_guest_payments as ( + select + date, + dimension, + dimension_value, + deposit_fees_in_gbp, + waiver_payments_in_gbp, + checkin_cover_fees_in_gbp, + total_guest_payments_in_gbp + from {{ ref("int_core__mtd_guest_payments_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.deposit_fees_in_gbp as old_deposit_fees_in_gbp, + n.deposit_fees_in_gbp as new_deposit_fees_in_gbp, + coalesce(o.deposit_fees_in_gbp, 0) + - coalesce(n.deposit_fees_in_gbp, 0) as diff_deposit_fees_in_gbp, + o.waiver_payments_in_gbp as old_waiver_payments_in_gbp, + n.waiver_payments_in_gbp as new_waiver_payments_in_gbp, + coalesce(o.waiver_payments_in_gbp, 0) + - coalesce(n.waiver_payments_in_gbp, 0) as diff_waiver_payments_in_gbp, + o.checkin_cover_fees_in_gbp as old_checkin_cover_fees_in_gbp, + n.checkin_cover_fees_in_gbp as new_checkin_cover_fees_in_gbp, + coalesce(o.checkin_cover_fees_in_gbp, 0) - coalesce( + n.checkin_cover_fees_in_gbp, 0 + ) as diff_checkin_cover_fees_in_gbp, + o.total_guest_payments_in_gbp as old_total_guest_payments_in_gbp, + n.total_guest_payments_in_gbp as new_total_guest_payments_in_gbp, + coalesce(o.total_guest_payments_in_gbp, 0) - coalesce( + n.total_guest_payments_in_gbp, 0 + ) as diff_total_guest_payments_in_gbp + from old_guest_payments o + full outer join + new_guest_payments n + on o.date = n.date + and o.dimension = n.dimension + and o.dimension_value = n.dimension_value + ) +select * +from comparison +where + diff_deposit_fees_in_gbp <> 0 + or diff_waiver_payments_in_gbp <> 0 + or diff_checkin_cover_fees_in_gbp <> 0 + or diff_total_guest_payments_in_gbp <> 0 +order by date desc, diff_total_guest_payments_in_gbp desc