This PR aims to propagate the computation of guest revenue model into the aggregated models. Changes: - I changed the logic on `int_mtd_guest_revenue_metrics` since it was still using the old computation of the relative increment within the same model. Basically, I removed it (last part of the query). The rest of changes in this model are just formatting. - I also applied the formatting in the int_mtd_vs_previous_year_metrics, mainly changing the macro calls from **'**xyz**'** to **"**xyz**"**. What's new: - `int_mtd_guest_revenue_metrics` into `int_mtd_vs_previous_year_metrics`, by adding `total_guest_revenue_in_gbp` and `total_guest_payments_in_gbp`. Additionally, with the new logic, for the first time we're able to compute **weighted metrics** coming from different sources. Specifically, it computes the weighted measures per guest journey completed and guest journey with payment. - Similar behavior on the 'by deal', adding `int_monthly_guest_revenue_history_by_deal` into `int_monthly_aggregated_metrics` and similar computation This model does not affect the exposing logic still, meaning these metrics won't be exposed in the report. This will come in a separated PR. Related work items: #18107
79 lines
3 KiB
SQL
79 lines
3 KiB
SQL
/*
|
|
This model provides Month-To-Date (MTD) based on Guest Revenue metrics.
|
|
|
|
*/
|
|
{% set revenue_verification_payment_type_items = "('FEE','WAIVER','CHECKINCOVER')" %}
|
|
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
|
|
{% set waiver_items = "('DAMAGE WAVER','DAMAGE WAIVER')" %}
|
|
|
|
{{ config(materialized="table", unique_key="date") }}
|
|
with
|
|
int_core__verification_payments as (
|
|
select * from {{ ref("int_core__verification_payments") }}
|
|
),
|
|
int_xero__credit_note_line_items as (
|
|
select * from {{ ref("int_xero__credit_note_line_items") }}
|
|
),
|
|
int_xero__credit_notes as (select * from {{ ref("int_xero__credit_notes") }}),
|
|
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
|
|
|
-- Paid Guest Revenue MTD --
|
|
guest_payments_year_month as (
|
|
select
|
|
d.date,
|
|
sum(vp.amount_in_gbp) as total_guest_payments_in_gbp,
|
|
sum(
|
|
case
|
|
when
|
|
upper(vp.verification_payment_type)
|
|
in {{ revenue_verification_payment_type_items }}
|
|
then vp.amount_in_gbp
|
|
else null
|
|
end
|
|
) as total_guest_income_in_gbp
|
|
from int_dates_mtd d
|
|
inner join
|
|
int_core__verification_payments vp
|
|
on extract(year from vp.payment_paid_date_utc) = d.year
|
|
and extract(month from vp.payment_paid_date_utc) = d.month
|
|
and extract(day from vp.payment_paid_date_utc) <= d.day
|
|
where upper(vp.payment_status) = {{ var("paid_payment_state") }}
|
|
group by 1
|
|
),
|
|
-- Waiver Credit Notes MTD --
|
|
-- We need to get the credited waivers for those
|
|
-- host-takes-waiver cases
|
|
waiver_credit_notes as (
|
|
select d.date, sum(cnli.line_amount_wo_taxes_in_gbp) as waiver_fees_credited
|
|
from int_dates_mtd d
|
|
inner join
|
|
int_xero__credit_notes cn
|
|
on extract(year from cn.credit_note_issued_date_utc) = d.year
|
|
and extract(month from cn.credit_note_issued_date_utc) = d.month
|
|
and extract(day from cn.credit_note_issued_date_utc) <= d.day
|
|
inner join
|
|
int_xero__credit_note_line_items cnli
|
|
on cn.id_credit_note = cnli.id_credit_note
|
|
where
|
|
upper(cn.credit_note_status) in {{ relevant_document_statuses }}
|
|
and upper(cnli.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,
|
|
nullif(gpym.total_guest_payments_in_gbp, 0) as total_guest_payments_in_gbp,
|
|
-- Deduct from total guest income the host-takes-waiver income
|
|
nullif(
|
|
coalesce(gpym.total_guest_income_in_gbp, 0)
|
|
- coalesce(wcn.waiver_fees_credited, 0),
|
|
0
|
|
) as total_guest_revenue_in_gbp
|
|
from int_dates_mtd d
|
|
left join guest_payments_year_month gpym on gpym.date = d.date
|
|
left join waiver_credit_notes wcn on wcn.date = d.date
|