data-dwh-dbt-project/models/intermediate/cross/int_mtd_guest_revenue_metrics.sql
Oriol Roqué Paniagua fbd2bdd7f4 Merged PR 2381: Adding submetrics of guest revenue
Adding submetrics of guest revenue:
- deposit fees
- checkin cover fees
- waiver payments

all of this adds up to
- guest income

and the revenue is computed by subtracting waivers paid to hosts

Related work items: #18787
2024-07-23 13:50:03 +00:00

75 lines
2.7 KiB
SQL

/*
This model provides Month-To-Date (MTD) based on Guest Revenue metrics.
*/
{% set deposit_fees_verification_payment_type_items = "('FEE')" %}
{% set waiver_fees_verification_payment_type_items = "('WAIVER')" %}
{% set checkin_cover_fees_verification_payment_type_items = "('CHECKINCOVER')" %}
{{ config(materialized="table", unique_key="date") }}
with
int_core__verification_payments as (
select * from {{ ref("int_core__verification_payments") }}
),
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 {{ deposit_fees_verification_payment_type_items }}
then vp.amount_in_gbp
else null
end
) as deposit_fees_in_gbp,
sum(
case
when
upper(vp.verification_payment_type)
in {{ waiver_fees_verification_payment_type_items }}
then vp.amount_in_gbp
else null
end
) as waiver_payments_in_gbp,
sum(
case
when
upper(vp.verification_payment_type)
in {{ checkin_cover_fees_verification_payment_type_items }}
then vp.amount_in_gbp
else null
end
) as checkin_cover_fees_in_gbp
from int_dates_mtd d
inner join
int_core__verification_payments vp
on date_trunc('month', vp.payment_paid_date_utc)::date = d.first_day_month
and extract(day from vp.payment_paid_date_utc) <= d.day
where upper(vp.payment_status) = {{ var("paid_payment_state") }}
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.deposit_fees_in_gbp, 0) as deposit_fees_in_gbp,
nullif(gpym.waiver_payments_in_gbp, 0) as waiver_payments_in_gbp,
nullif(gpym.checkin_cover_fees_in_gbp, 0) as checkin_cover_fees_in_gbp,
nullif(gpym.total_guest_payments_in_gbp, 0) as total_guest_payments_in_gbp,
nullif(
coalesce(gpym.deposit_fees_in_gbp, 0)
+ coalesce(gpym.waiver_payments_in_gbp, 0)
+ coalesce(gpym.checkin_cover_fees_in_gbp, 0),
0
) as total_guest_income_in_gbp
from int_dates_mtd d
left join guest_payments_year_month gpym on gpym.date = d.date