# Description Changes: * **Main change:** exclusion of KYG lite users of the segmentation of Business Scope. These are "freemium" users, kind of demo users, that shouldn't have any real impact in terms of revenue. These are in New Dash, but do not have a deal. The problem is that we don't want to consider them as New Dash, but the current condition was making them appear as Old Dash. This PR fixes this by handling the logic for backend related models. Note that Xero remains unaffected - this is based on Deal, and these users do not have Deal. * Small data quality fix I noticed while debugging KYG lite cases. It's better to use the "is upgraded service" from the staging original tables rather than the one with the prices. If a user does not have a currency (which can be the case for KYG lite users), then the coalesce would tag any service as not upgraded, which is not true. # 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
100 lines
3.7 KiB
SQL
100 lines
3.7 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", "business_scope", "has_id_check"],
|
|
)
|
|
}}
|
|
|
|
select
|
|
-- Unique Key --
|
|
icvp.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
|
|
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
|
|
where upper(icvp.payment_status) = {{ var("paid_payment_state") }}
|
|
group by 1, 2, 3, 4, 5, 6
|