data-dwh-dbt-project/models/intermediate/xero/int_xero__mtd_invoicing_metrics.sql
Oriol Roqué Paniagua bf473ab971 Merged PR 2292: Propagate invoicing metrics for KPIs
This PR aims to propagate the invoicing metrics through the DWH. It does not expose them to users, yet.

This PR effectively computes the following metrics, for both the "global" view (MTD) and the "by deal" view (by_deal):
- Invoiced Operator Revenue
- Host Resolution Count of Payments
- Host Resolution Amount Paid

With these 3 new metrics, we're able to combine them with the existing ones to compute:
- Total Revenue
- Total Revenue per Booking Created
- Total Revenue per Guest Journey Created
- Total Revenue per Deal Booked in Month
- Total Revenue per Listings Booked in Month

You'll also note that I've included standalone metrics for booking fees, listing fees, verification fees and waiver payments. This will not be exposed in this batch 2, but based on the conversation with Finance, will clearly make it for batch 3. I just find it easier to add it now, since it's straight forward.

Main changes:
- `int_mtd_vs_previous_year_metrics` now computes all the above mentioned metrics
- `int_monthly_aggregated_metrics_history_by_deal` now computes all the above mentioned metrics, except Total Revenue per Deal Booked in Month since it does not make sense for the deal view. Additionally, I took the opportunity to include the missing metrics from listings (accommodations). The goal is not necessarily to display them, but at least compute it on our side.

Additional changes:
- In `int_xero__mtd_invoicing_metrics` and `int_xero__monthly_invoicing_history_by_deal`, there's a very silly name change to keep the same convention for fees: from `xero_operator_net_fees` to `xero_operator_net_fees_in_gbp`
- I applied additional changes in `int_monthly_aggregated_metrics_history_by_deal` with the goal to keep the same format as we have in `int_mtd_vs_previous_year_metrics`, this meaning:
1 - explicit alias naming (from `gj` to `guest_journeys`)
2 - keep a similar arrangement of metrics, and clearly separate scopes depending on the metric type
3 - Re-apply autoformatting

Related work items: #18108, #18109, #18110
2024-07-15 07:33:55 +00:00

111 lines
4.3 KiB
SQL

/*
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_in_gbp,
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