# 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
141 lines
5.9 KiB
SQL
141 lines
5.9 KiB
SQL
{% 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
|