# Description Changes: * On Created and Check Out Bookings daily models, the determination of New Dash bookings now uses `int_core__booking_summary`. This does not change the output, but will be more consistent for other KPIs. * Adds the categorisation of `dash_source` in all daily metric models that depend on Verification Requests (Guest Journeys). This affects GJ Created, GJ Started, GJ Completed, GJ w. Payment and Guest Payments. Note that the next aggregations (monthly, mtd, agg_monthly, agg_mtd) are not created yet. This will be done in a separated PR. # 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. - [X] 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: #27356
92 lines
3.3 KiB
SQL
92 lines
3.3 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')" %}
|
|
{% set id_check = "('GOVERNMENTID')" %}
|
|
|
|
{{
|
|
config(
|
|
materialized="table",
|
|
unique_key=["date", "id_deal", "dash_source", "has_id_check"],
|
|
)
|
|
}}
|
|
|
|
select
|
|
-- Unique Key --
|
|
icvp.payment_paid_date_utc as date,
|
|
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
|
case
|
|
when icbs.id_booking is not null then 'New Dash' else 'Old Dash'
|
|
end as dash_source,
|
|
case
|
|
when icv.id_verification is null then 'W/O Id Check' else 'With Id Check'
|
|
end as has_id_check,
|
|
-- 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("stg_core__verification") }} as icv
|
|
on icv.id_verification_request = icvr.id_verification_request
|
|
and upper(icv.verification) = {{ id_check }}
|
|
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
|
|
left join
|
|
{{ ref("int_core__booking_summary") }} as icbs
|
|
on icvp.id_verification_request = icbs.id_verification_request
|
|
and icbs.is_user_in_new_dash = true
|
|
and icbs.is_missing_id_deal = false
|
|
where upper(icvp.payment_status) = {{ var("paid_payment_state") }}
|
|
group by 1, 2, 3, 4, 5, 6
|