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
This commit is contained in:
parent
9585b759a4
commit
3ecbcb2c49
7 changed files with 697 additions and 10 deletions
92
tests/tmp_kpis_refactor_equivalent_guest_payments.sql
Normal file
92
tests/tmp_kpis_refactor_equivalent_guest_payments.sql
Normal file
|
|
@ -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
|
||||
Loading…
Add table
Add a link
Reference in a new issue