# Description Adds 2 new metrics: - xero_host_resolution_amount_paid_in_gbp - xero_host_resolution_payment_count Effectively it will split the "real" invoicing sources of revenue from "host resolution payments". This was already reading from 2 different Xero models (bank transactions vs. sales). We have as usual: - 1 Daily metric model - 2 MTD/Monthly metric model - 2 MTD/Monthly agg model (I already changed the name to agg instead of aggregated) - 1 test to compare the values match the current setup # 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
80 lines
3 KiB
SQL
80 lines
3 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_host_resolutions as (
|
|
select
|
|
end_date as date,
|
|
dimension,
|
|
dimension_value,
|
|
xero_host_resolution_amount_paid_in_gbp,
|
|
xero_host_resolution_payment_count
|
|
from {{ ref("int_kpis__agg_mtd_host_resolutions") }}
|
|
where
|
|
end_date >= '{{ min_date }}'
|
|
and dimension in {{ dimensions }}
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
new_monthly_host_resolutions as (
|
|
select
|
|
end_date as date,
|
|
dimension,
|
|
dimension_value,
|
|
xero_host_resolution_amount_paid_in_gbp,
|
|
xero_host_resolution_payment_count
|
|
from {{ ref("int_kpis__agg_monthly_host_resolutions") }}
|
|
where
|
|
end_date >= '{{ min_date }}'
|
|
and dimension in {{ dimensions }}
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
new_host_resolutions as (
|
|
select *
|
|
from new_mtd_host_resolutions
|
|
union all
|
|
select *
|
|
from new_monthly_host_resolutions
|
|
),
|
|
old_host_resolutions as (
|
|
select
|
|
date,
|
|
dimension,
|
|
dimension_value,
|
|
xero_host_resolution_amount_paid_in_gbp,
|
|
xero_host_resolution_payment_count
|
|
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_host_resolution_amount_paid_in_gbp
|
|
as old_xero_host_resolution_amount_paid_in_gbp,
|
|
n.xero_host_resolution_amount_paid_in_gbp
|
|
as new_xero_host_resolution_amount_paid_in_gbp,
|
|
coalesce(o.xero_host_resolution_amount_paid_in_gbp, 0) - coalesce(
|
|
n.xero_host_resolution_amount_paid_in_gbp, 0
|
|
) as diff_xero_host_resolution_amount_paid_in_gbp,
|
|
o.xero_host_resolution_payment_count
|
|
as old_xero_host_resolution_payment_count,
|
|
n.xero_host_resolution_payment_count
|
|
as new_xero_host_resolution_payment_count,
|
|
coalesce(o.xero_host_resolution_payment_count, 0) - coalesce(
|
|
n.xero_host_resolution_payment_count, 0
|
|
) as diff_xero_host_resolution_payment_count
|
|
from old_host_resolutions o
|
|
full outer join
|
|
new_host_resolutions n
|
|
on o.date = n.date
|
|
and o.dimension = n.dimension
|
|
and o.dimension_value = n.dimension_value
|
|
)
|
|
select *
|
|
from comparison
|
|
where
|
|
diff_xero_host_resolution_amount_paid_in_gbp <> 0
|
|
or diff_xero_host_resolution_payment_count <> 0
|
|
order by date desc
|