# Description Adds Guest Payments metrics, namely: * deposit_fees_in_gbp * waiver_payments_in_gbp * checkin_cover_fees_in_gbp * total_guest_payments_in_gbp It includes: * Daily model * Monthly/MTD without dimension aggregates * Monthly/MTD with dimension aggregates * Schema entries for the abovementioned 5 models * Temporary test to compare the different metrics against current production KPIs # Checklist - [X] The edited models and dependants run properly with production data. - [X] The edited models are sufficiently documented. - [X] The edited models contain PK tests, and I've ran and passed them. - [NA] I have checked for DRY opportunities with other models and docs. - [X] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #23453
71 lines
2.6 KiB
SQL
71 lines
2.6 KiB
SQL
{% 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", "id_deal"]) }}
|
|
|
|
select
|
|
-- Unique Key --
|
|
icvp.payment_paid_date_utc as date,
|
|
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
|
-- Dimensions --
|
|
coalesce(
|
|
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
|
) as main_billing_country_iso_3_per_deal,
|
|
coalesce(
|
|
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
|
|
) as active_accommodations_per_deal_segmentation,
|
|
-- Metrics --
|
|
sum(
|
|
case
|
|
when
|
|
upper(icvp.verification_payment_type)
|
|
in {{ deposit_fees_verification_payment_type_items }}
|
|
then icvp.amount_without_taxes_in_gbp
|
|
else null
|
|
end
|
|
) as deposit_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when
|
|
upper(icvp.verification_payment_type)
|
|
in {{ waiver_fees_verification_payment_type_items }}
|
|
then icvp.amount_without_taxes_in_gbp
|
|
else null
|
|
end
|
|
) as waiver_payments_in_gbp,
|
|
sum(
|
|
case
|
|
when
|
|
upper(icvp.verification_payment_type)
|
|
in {{ checkin_cover_fees_verification_payment_type_items }}
|
|
then icvp.amount_without_taxes_in_gbp
|
|
else null
|
|
end
|
|
) as checkin_cover_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when
|
|
upper(icvp.verification_payment_type)
|
|
in {{ checkin_cover_fees_verification_payment_type_items }}
|
|
or upper(icvp.verification_payment_type)
|
|
in {{ waiver_fees_verification_payment_type_items }}
|
|
or upper(icvp.verification_payment_type)
|
|
in {{ deposit_fees_verification_payment_type_items }}
|
|
then icvp.amount_without_taxes_in_gbp
|
|
else null
|
|
end
|
|
) as total_guest_payments_in_gbp
|
|
from {{ ref("int_core__verification_payments", version=2) }} as icvp
|
|
left join
|
|
{{ ref("int_core__verification_requests") }} as icvr
|
|
on icvp.id_verification_request = icvr.id_verification_request
|
|
left join
|
|
{{ ref("int_core__user_host") }} as icuh on icvr.id_user_host = icuh.id_user_host
|
|
left join {{ ref("int_core__deal") }} as icd on icuh.id_deal = icd.id_deal
|
|
left join
|
|
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
|
on icuh.id_deal = icmas.id_deal
|
|
and icvp.payment_paid_date_utc = icmas.date
|
|
where upper(icvp.payment_status) = {{ var("paid_payment_state") }}
|
|
group by 1, 2, 3, 4
|