{% set deposit_fees_product_payment_items = "('FEE')" %} {% set waiver_fees_product_payment_items = "('WAIVER')" %} {% set checkin_cover_fees_product_payment_items = "('CHECKINCOVER')" %} {% set stay_disrupt_fees_product_payment_items = "('STAYDISRUPT')" %} {% set id_check_verification = "('GOVERNMENTID')" %} {{ config( materialized="table", unique_key=["date", "id_deal", "business_scope", "has_id_check"], ) }} select -- Unique Key -- icgjp.payment_paid_date_utc as date, coalesce(icuh.id_deal, 'UNSET') as id_deal, case -- 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' end as business_scope, 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 icgjp.product_name in {{ deposit_fees_product_payment_items }} then icgjp.amount_without_taxes_in_gbp else null end ) as deposit_fees_in_gbp, sum( case when icgjp.product_name in {{ waiver_fees_product_payment_items }} then icgjp.amount_without_taxes_in_gbp else null end ) as waiver_payments_in_gbp, sum( case when icgjp.product_name in {{ checkin_cover_fees_product_payment_items }} then icgjp.amount_without_taxes_in_gbp else null end ) as checkin_cover_fees_in_gbp, sum( case when icgjp.product_name in {{ stay_disrupt_fees_product_payment_items }} then icgjp.amount_without_taxes_in_gbp else null end ) as stay_disrupt_fees_in_gbp, sum( case when 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 }} or icgjp.product_name in {{ stay_disrupt_fees_product_payment_items }} then icgjp.amount_without_taxes_in_gbp else null end ) as total_guest_payments_in_gbp from {{ ref("int_core__guest_journey_payments") }} as icgjp left join {{ ref("stg_core__verification") }} as icv on icv.id_verification_request = icgjp.id_verification_request and upper(icv.verification) = {{ id_check_verification }} left join {{ ref("int_core__user_host") }} as icuh on icgjp.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 icgjp.payment_paid_date_utc = icmas.date left join {{ ref("int_core__booking_summary") }} as icbs on icgjp.id_verification_request = icbs.id_verification_request where icgjp.is_paid_status = true group by 1, 2, 3, 4, 5, 6