2025-05-12 10:56:02 +00:00
|
|
|
{% set deposit_fees_product_payment_items = "('FEE')" %}
|
|
|
|
|
{% set waiver_fees_product_payment_items = "('WAIVER')" %}
|
|
|
|
|
{% set checkin_cover_fees_product_payment_items = "('CHECKINCOVER')" %}
|
|
|
|
|
{% set id_check_verification = "('GOVERNMENTID')" %}
|
2024-10-31 09:03:15 +00:00
|
|
|
|
2025-02-11 07:12:46 +00:00
|
|
|
{{
|
|
|
|
|
config(
|
|
|
|
|
materialized="table",
|
2025-02-11 16:19:33 +00:00
|
|
|
unique_key=["date", "id_deal", "business_scope", "has_id_check"],
|
2025-02-11 07:12:46 +00:00
|
|
|
)
|
|
|
|
|
}}
|
2024-10-31 09:03:15 +00:00
|
|
|
|
|
|
|
|
select
|
|
|
|
|
-- Unique Key --
|
2025-05-12 10:56:02 +00:00
|
|
|
icgjp.payment_paid_date_utc as date,
|
2024-10-31 09:03:15 +00:00
|
|
|
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
2025-02-11 07:12:46 +00:00
|
|
|
case
|
2025-02-13 09:38:43 +00:00
|
|
|
-- New Dash users with a booking and a deal
|
|
|
|
|
when
|
|
|
|
|
icbs.id_booking is not null
|
|
|
|
|
and icbs.is_user_in_new_dash = true
|
|
|
|
|
and icbs.is_missing_id_deal = false
|
|
|
|
|
then 'New Dash'
|
|
|
|
|
-- Old Dash users if there is no booking or the user is not in the new dash
|
|
|
|
|
when icbs.id_booking is null or icbs.is_user_in_new_dash = false
|
|
|
|
|
then 'Old Dash'
|
|
|
|
|
-- Rest of the cases, includes KYG Lite users
|
|
|
|
|
else 'UNSET'
|
2025-02-11 16:19:33 +00:00
|
|
|
end as business_scope,
|
2024-11-06 11:28:50 +01:00
|
|
|
case
|
2024-11-06 12:34:33 +01:00
|
|
|
when icv.id_verification is null then 'W/O Id Check' else 'With Id Check'
|
2024-11-06 11:28:50 +01:00
|
|
|
end as has_id_check,
|
2024-10-31 09:03:15 +00:00
|
|
|
-- 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
|
2025-05-12 10:56:02 +00:00
|
|
|
when icgjp.product_name in {{ deposit_fees_product_payment_items }}
|
|
|
|
|
then icgjp.amount_without_taxes_in_gbp
|
2024-10-31 09:03:15 +00:00
|
|
|
else null
|
|
|
|
|
end
|
|
|
|
|
) as deposit_fees_in_gbp,
|
|
|
|
|
sum(
|
|
|
|
|
case
|
2025-05-12 10:56:02 +00:00
|
|
|
when icgjp.product_name in {{ waiver_fees_product_payment_items }}
|
|
|
|
|
then icgjp.amount_without_taxes_in_gbp
|
2024-10-31 09:03:15 +00:00
|
|
|
else null
|
|
|
|
|
end
|
|
|
|
|
) as waiver_payments_in_gbp,
|
|
|
|
|
sum(
|
|
|
|
|
case
|
2025-05-12 10:56:02 +00:00
|
|
|
when icgjp.product_name in {{ checkin_cover_fees_product_payment_items }}
|
|
|
|
|
then icgjp.amount_without_taxes_in_gbp
|
2024-10-31 09:03:15 +00:00
|
|
|
else null
|
|
|
|
|
end
|
|
|
|
|
) as checkin_cover_fees_in_gbp,
|
|
|
|
|
sum(
|
|
|
|
|
case
|
|
|
|
|
when
|
2025-05-12 10:56:02 +00:00
|
|
|
icgjp.product_name in {{ checkin_cover_fees_product_payment_items }}
|
|
|
|
|
or icgjp.product_name in {{ waiver_fees_product_payment_items }}
|
|
|
|
|
or icgjp.product_name in {{ deposit_fees_product_payment_items }}
|
|
|
|
|
then icgjp.amount_without_taxes_in_gbp
|
2024-10-31 09:03:15 +00:00
|
|
|
else null
|
|
|
|
|
end
|
2024-11-06 16:24:57 +01:00
|
|
|
) as total_guest_payments_in_gbp
|
2025-05-12 10:56:02 +00:00
|
|
|
from {{ ref("int_core__guest_journey_payments") }} as icgjp
|
2024-11-06 11:28:50 +01:00
|
|
|
left join
|
|
|
|
|
{{ ref("stg_core__verification") }} as icv
|
2025-05-12 10:56:02 +00:00
|
|
|
on icv.id_verification_request = icgjp.id_verification_request
|
|
|
|
|
and upper(icv.verification) = {{ id_check_verification }}
|
2024-10-31 09:03:15 +00:00
|
|
|
left join
|
2025-05-12 10:56:02 +00:00
|
|
|
{{ ref("int_core__user_host") }} as icuh on icgjp.id_user_host = icuh.id_user_host
|
2024-10-31 09:03:15 +00:00
|
|
|
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
|
2025-05-12 10:56:02 +00:00
|
|
|
and icgjp.payment_paid_date_utc = icmas.date
|
2025-02-11 07:12:46 +00:00
|
|
|
left join
|
|
|
|
|
{{ ref("int_core__booking_summary") }} as icbs
|
2025-05-12 10:56:02 +00:00
|
|
|
on icgjp.id_verification_request = icbs.id_verification_request
|
|
|
|
|
where icgjp.is_paid_status = true
|
2025-02-11 07:12:46 +00:00
|
|
|
group by 1, 2, 3, 4, 5, 6
|