data-dwh-dbt-project/tests/tmp_kpis_refactor_equivalent_guest_payments.sql

93 lines
3.5 KiB
MySQL
Raw Normal View History

{% 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