/* 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 ), main_kpi as ( -- Final aggregation of subqueries -- select d.year, d.month, d.day, d.date, d.is_end_of_month, d.is_current_month, coalesce(gpym.total_guest_payments_in_gbp,0) as total_guest_payments_in_gbp, -- Deduct from total guest income the host-takes-waiver income coalesce(gpym.total_guest_income_in_gbp,0) - coalesce(wcn.waiver_fees_credited,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 ) -- Pivoting to get previous year for each line & computing relative increment -- (rel_incr) -- select a.year, a.month, a.day, a.is_end_of_month, a.is_current_month, a.date, b.date as previous_year_date, a.total_guest_payments_in_gbp, b.total_guest_payments_in_gbp as previous_year_total_guest_payments_in_gbp, cast(a.total_guest_payments_in_gbp as decimal) / b.total_guest_payments_in_gbp - 1 as relative_increment_total_guest_payments_in_gbp, a.total_guest_revenue_in_gbp, b.total_guest_revenue_in_gbp as previous_year_total_guest_revenue_in_gbp, cast(a.total_guest_revenue_in_gbp as decimal) / b.total_guest_revenue_in_gbp - 1 as relative_increment_total_guest_revenue_in_gbp from main_kpi a left join main_kpi b on a.month = b.month and a.year = b.year + 1 where (a.is_end_of_month = 1 or (a.is_current_month = 1 and a.day = b.day))