Merged PR 5183: Switch dependencies on verification payments for KPIs models
# Description Switches the 3 KPIs models that used int_core__verification_payments_v2 to now use int_core__guest_journey_payments. Audit successful. # 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: #30024
This commit is contained in:
parent
b1faa83156
commit
c6b61856f0
3 changed files with 34 additions and 51 deletions
|
|
@ -1,4 +1,4 @@
|
|||
{% set id_check = "GovernmentId" %}
|
||||
{% set id_check_verification = "GovernmentId" %}
|
||||
|
||||
{{
|
||||
config(
|
||||
|
|
@ -21,7 +21,7 @@ select
|
|||
b.check_in_date_utc as date,
|
||||
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when vp.id_verification_to_payment is null
|
||||
when icgjp.id_guest_journey_payment is null
|
||||
then 'W/O Payment'
|
||||
else 'With Payment'
|
||||
end as has_payment,
|
||||
|
|
@ -110,12 +110,12 @@ left join
|
|||
on icuh.id_deal = icmas.id_deal
|
||||
and b.check_in_date_utc = icmas.date
|
||||
left join
|
||||
{{ ref("int_core__verification_payments") }} as vp
|
||||
on vp.id_verification_request = vr.id_verification_request
|
||||
{{ ref("int_core__guest_journey_payments") }} as icgjp
|
||||
on icgjp.id_verification_request = vr.id_verification_request
|
||||
left join
|
||||
{{ ref("stg_core__verification") }} as v
|
||||
on v.id_verification_request = vr.id_verification_request
|
||||
and v.verification = '{{ id_check }}'
|
||||
and v.verification = '{{ id_check_verification }}'
|
||||
left join
|
||||
{{ ref("int_core__guest_satisfaction_responses") }} as gsr
|
||||
on gsr.id_verification_request = vr.id_verification_request
|
||||
|
|
|
|||
|
|
@ -2,12 +2,11 @@
|
|||
with
|
||||
first_payment_per_verification_request as (
|
||||
select
|
||||
vp.id_verification_request,
|
||||
min(vp.payment_paid_date_utc) as first_payment_paid_date_utc
|
||||
from {{ ref("int_core__verification_payments", version=2) }} vp
|
||||
where
|
||||
upper(vp.payment_status) = {{ var("paid_payment_state") }}
|
||||
and vp.id_verification_request is not null
|
||||
icgjp.id_verification_request,
|
||||
min(icgjp.id_user_host) as id_user_host, -- User Host should always be the same per VR
|
||||
min(icgjp.payment_paid_date_utc) as first_payment_paid_date_utc
|
||||
from {{ ref("int_core__guest_journey_payments") }} icgjp
|
||||
where icgjp.is_paid_status = true and icgjp.id_verification_request is not null
|
||||
group by 1
|
||||
)
|
||||
select
|
||||
|
|
@ -35,13 +34,9 @@ select
|
|||
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
|
||||
) as active_accommodations_per_deal_segmentation,
|
||||
-- Metrics --
|
||||
count(distinct icvr.id_verification_request) as guest_journeys_with_payment
|
||||
count(distinct p.id_verification_request) as guest_journeys_with_payment
|
||||
from first_payment_per_verification_request as p
|
||||
left join
|
||||
{{ ref("int_core__verification_requests") }} as icvr
|
||||
on p.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__user_host") }} as icuh on p.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
|
||||
|
|
|
|||
|
|
@ -1,7 +1,7 @@
|
|||
{% 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')" %}
|
||||
{% 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')" %}
|
||||
|
||||
{{
|
||||
config(
|
||||
|
|
@ -12,7 +12,7 @@
|
|||
|
||||
select
|
||||
-- Unique Key --
|
||||
icvp.payment_paid_date_utc as date,
|
||||
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
|
||||
|
|
@ -40,61 +40,49 @@ select
|
|||
-- Metrics --
|
||||
sum(
|
||||
case
|
||||
when
|
||||
upper(icvp.verification_payment_type)
|
||||
in {{ deposit_fees_verification_payment_type_items }}
|
||||
then icvp.amount_without_taxes_in_gbp
|
||||
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
|
||||
upper(icvp.verification_payment_type)
|
||||
in {{ waiver_fees_verification_payment_type_items }}
|
||||
then icvp.amount_without_taxes_in_gbp
|
||||
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
|
||||
upper(icvp.verification_payment_type)
|
||||
in {{ checkin_cover_fees_verification_payment_type_items }}
|
||||
then icvp.amount_without_taxes_in_gbp
|
||||
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
|
||||
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
|
||||
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
|
||||
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
|
||||
from {{ ref("int_core__guest_journey_payments") }} as icgjp
|
||||
left join
|
||||
{{ ref("stg_core__verification") }} as icv
|
||||
on icv.id_verification_request = icvr.id_verification_request
|
||||
and upper(icv.verification) = {{ id_check }}
|
||||
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 icvr.id_user_host = icuh.id_user_host
|
||||
{{ 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 icvp.payment_paid_date_utc = icmas.date
|
||||
and icgjp.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") }}
|
||||
on icgjp.id_verification_request = icbs.id_verification_request
|
||||
where icgjp.is_paid_status = true
|
||||
group by 1, 2, 3, 4, 5, 6
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue