112 lines
4.3 KiB
MySQL
112 lines
4.3 KiB
MySQL
|
|
/*
|
||
|
|
This model provides Month-To-Date (MTD) based on anything related to
|
||
|
|
invoicing metrics. This includes Operator (Host) fees, waiver payments,
|
||
|
|
and Host Resolutions.
|
||
|
|
|
||
|
|
*/
|
||
|
|
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
|
||
|
|
{% set booking_fee_items = "('EU BOOKING FEE','ZAR BOOKINGS','BOOKING FEE - NON-UK','USD BOOKINGS','CAD BOOKINGS','BOOKING FEE - UK','AUD BOOKINGS')" %}
|
||
|
|
{% set listing_fee_items = "('USD LISTINGS','LISTING FEE - NON UK','ZAR LISTINGS','CAD LISTINGS','LISTING FEE - UK','AUD LISTINGS','EU LISTINGS')" %}
|
||
|
|
{% set waiver_items = "('DAMAGE WAVER', 'DAMAGE WAIVER')" %}
|
||
|
|
{% set verification_fee_items = "('VERIFICATION FEE')" %}
|
||
|
|
{% set resolutions_host_payment_account_name = "('RESOLUTIONS - HOST PAYMENT')" %}
|
||
|
|
|
||
|
|
{{ config(materialized="table", unique_key="date") }}
|
||
|
|
with
|
||
|
|
int_xero__sales_denom_mart as (
|
||
|
|
select * from {{ ref("int_xero__sales_denom_mart") }}
|
||
|
|
),
|
||
|
|
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||
|
|
int_xero__bank_transaction_line_items as (
|
||
|
|
select * from {{ ref("int_xero__bank_transaction_line_items") }}
|
||
|
|
),
|
||
|
|
int_xero__bank_transactions as (
|
||
|
|
select * from {{ ref("int_xero__bank_transactions") }}
|
||
|
|
),
|
||
|
|
|
||
|
|
resolution_host_payment as (
|
||
|
|
select
|
||
|
|
d.date,
|
||
|
|
sum(
|
||
|
|
btli.line_amount_wo_taxes_in_gbp
|
||
|
|
) as xero_host_resolution_amount_paid_in_gbp,
|
||
|
|
count(distinct bt.id_bank_transaction) as xero_host_resolution_payment_count
|
||
|
|
from int_dates_mtd d
|
||
|
|
inner join
|
||
|
|
int_xero__bank_transactions bt
|
||
|
|
on date_trunc('month', bt.transaction_date_utc)::date = d.first_day_month
|
||
|
|
and extract(day from bt.transaction_date_utc) <= d.day
|
||
|
|
inner join
|
||
|
|
int_xero__bank_transaction_line_items btli
|
||
|
|
on bt.id_bank_transaction = btli.id_bank_transaction
|
||
|
|
and upper(btli.account_name) in {{ resolutions_host_payment_account_name }}
|
||
|
|
group by 1
|
||
|
|
),
|
||
|
|
host_net_fees as (
|
||
|
|
select
|
||
|
|
d.date,
|
||
|
|
sum(
|
||
|
|
case
|
||
|
|
when upper(sdm.item_code) in {{ booking_fee_items }}
|
||
|
|
then sdm.line_amount_wo_taxes_in_gbp
|
||
|
|
else 0
|
||
|
|
end
|
||
|
|
) as xero_booking_net_fees_in_gbp,
|
||
|
|
sum(
|
||
|
|
case
|
||
|
|
when upper(sdm.item_code) in {{ listing_fee_items }}
|
||
|
|
then sdm.line_amount_wo_taxes_in_gbp
|
||
|
|
else 0
|
||
|
|
end
|
||
|
|
) as xero_listing_net_fees_in_gbp,
|
||
|
|
sum(
|
||
|
|
case
|
||
|
|
when upper(sdm.item_code) in {{ verification_fee_items }}
|
||
|
|
then sdm.line_amount_wo_taxes_in_gbp
|
||
|
|
else 0
|
||
|
|
end
|
||
|
|
) as xero_verification_net_fees_in_gbp,
|
||
|
|
sum(
|
||
|
|
case
|
||
|
|
when upper(sdm.item_code) in {{ waiver_items }}
|
||
|
|
then sdm.line_amount_wo_taxes_in_gbp
|
||
|
|
else 0
|
||
|
|
end
|
||
|
|
) as xero_waiver_net_fees_in_gbp
|
||
|
|
from int_dates_mtd d
|
||
|
|
inner join
|
||
|
|
int_xero__sales_denom_mart sdm
|
||
|
|
on date_trunc('month', sdm.document_issued_date_utc) = d.first_day_month
|
||
|
|
and extract(day from sdm.document_issued_date_utc) <= d.day
|
||
|
|
where
|
||
|
|
upper(sdm.document_status) in {{ relevant_document_statuses }}
|
||
|
|
and (
|
||
|
|
upper(sdm.item_code) in {{ booking_fee_items }}
|
||
|
|
or upper(sdm.item_code) in {{ listing_fee_items }}
|
||
|
|
or upper(sdm.item_code) in {{ verification_fee_items }}
|
||
|
|
or upper(sdm.item_code) in {{ waiver_items }}
|
||
|
|
)
|
||
|
|
group by 1
|
||
|
|
|
||
|
|
)
|
||
|
|
-- Final aggregation of subqueries --
|
||
|
|
select
|
||
|
|
d.year,
|
||
|
|
d.month,
|
||
|
|
d.day,
|
||
|
|
d.date,
|
||
|
|
d.is_end_of_month,
|
||
|
|
d.is_current_month,
|
||
|
|
hnf.xero_booking_net_fees_in_gbp,
|
||
|
|
hnf.xero_listing_net_fees_in_gbp,
|
||
|
|
hnf.xero_verification_net_fees_in_gbp,
|
||
|
|
hnf.xero_booking_net_fees_in_gbp
|
||
|
|
+ hnf.xero_listing_net_fees_in_gbp
|
||
|
|
+ hnf.xero_verification_net_fees_in_gbp as xero_operator_net_fees,
|
||
|
|
hnf.xero_waiver_net_fees_in_gbp,
|
||
|
|
rhp.xero_host_resolution_amount_paid_in_gbp,
|
||
|
|
rhp.xero_host_resolution_payment_count
|
||
|
|
from int_dates_mtd d
|
||
|
|
left join resolution_host_payment rhp on rhp.date = d.date
|
||
|
|
left join host_net_fees hnf on hnf.date = d.date
|