Merged PR 5254: Optimized Guest Product Payments model

# Description

This PR introduces a new version (`v2`) for `int_core__guest_product_payments`.

The new version is expected to be semantically identical to `v1`, but have much better performance.

Because testing the validity of the semantically identity is hard (`v1` takes 30min to run on DWH HW), I've decided to make this PR to simply have both models at the same time in the DWH and leverage that to validate. To avoid mistakes, this PR ensures that all downstream dependants of `int_core__guest_product_payments` still point to `v1`, so "nothing changes".

Once we validate that `v2` is good to go, I'll make another PR to deprecate `v1` and repoint all downstreams to `v2`.

# 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: #30275
This commit is contained in:
Pablo Martin 2025-05-19 14:13:26 +00:00
commit 7b6f0d13f6
2 changed files with 150 additions and 0 deletions

View file

@ -0,0 +1,143 @@
{% set check_in_cover_as_id_verification_payment = "5" %}
{% set cut_off_date_check_in_cover_as_id_verification_payment = "'2025-06-08'" %}
{{ config(materialized="table") }}
with
stg_core__verification_to_payment as (
select *
from {{ ref("stg_core__verification_to_payment") }}
where
created_date_utc
<= date({{ cut_off_date_check_in_cover_as_id_verification_payment }})
and id_verification_payment_type
= {{ check_in_cover_as_id_verification_payment }}
),
stg_core__verification_payment_type as (
select * from {{ ref("stg_core__verification_payment_type") }}
),
stg_core__verification as (
select *
from {{ ref("stg_core__verification") }}
where
created_date_utc
<= date({{ cut_off_date_check_in_cover_as_id_verification_payment }})
),
stg_core__verification_request as (
select * from {{ ref("stg_core__verification_request") }}
),
stg_core__payment as (select * from {{ ref("stg_core__payment") }}),
stg_core__payment_status as (select * from {{ ref("stg_core__payment_status") }}),
int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }}),
stg_core__verification_request_guest_product_to_payment as (
select *
from {{ ref("stg_core__verification_request_guest_product_to_payment") }}
),
stg_core__verification_request_to_guest_product as (
select * from {{ ref("stg_core__verification_request_to_guest_product") }}
),
int_core__guest_products as (select * from {{ ref("int_core__guest_products") }}),
guest_product_payments_from_verification_flow as (
select
-- Tags Guest Product Payments that come from the legacy flow, namely
-- CheckInCover from Verification To Payment.
'leg_'
|| cast(vtp.id_verification_to_payment as text) as id_guest_product_payment,
vtp.id_payment,
vtp.created_at_utc,
vtp.updated_at_utc,
vtp.payment_due_at_utc,
vtp.payment_due_date_utc,
p.paid_at_utc as payment_paid_at_utc,
p.paid_date_utc as payment_paid_date_utc,
p.payment_reference,
vtp.refund_due_at_utc,
vtp.refund_due_date_utc,
p.refunded_at_utc as payment_refunded_at_utc,
p.refunded_date_utc as payment_refunded_date_utc,
p.refund_payment_reference,
vr.id_user_host,
vtp.id_guest_user as id_user_guest,
v.id_verification_request,
upper(vpt.verification_payment_type) as guest_product_name,
'VERIFICATION_PAYMENT' as guest_product_payment_source,
p.currency,
p.amount as total_amount_in_txn_currency,
p.amount * r.rate as total_amount_in_gbp,
upper(coalesce(ps.payment_status, 'UNKNOWN')) as payment_status,
p.notes
from stg_core__verification_to_payment vtp
left join stg_core__verification v on vtp.id_verification = v.id_verification
inner join
stg_core__verification_payment_type vpt
on vtp.id_verification_payment_type = vpt.id_verification_payment_type
left join stg_core__payment p on vtp.id_payment = p.id_payment
inner join
stg_core__payment_status ps on p.id_payment_status = ps.id_payment_status
inner join
int_simple_exchange_rates r
on vtp.payment_due_date_utc = r.rate_date_utc
and p.currency = r.from_currency
and r.to_currency = 'GBP'
left join
stg_core__verification_request vr
on v.id_verification_request = vr.id_verification_request
),
guest_product_payments_from_guest_product_flow as (
select
cast(
vrgptp.id_verification_request_guest_product_to_payment as text
) as id_guest_product_payment,
vrgptp.id_payment,
vrgptp.created_at_utc,
vrgptp.updated_at_utc,
-- For the new Guest Product flow, there's no concept of Due Date, as we
-- take the payment up front and if the payment fails, then they aren't
-- able to complete the Journey.
p.paid_at_utc as payment_due_at_utc,
p.paid_date_utc as payment_due_date_utc,
p.paid_at_utc as payment_paid_at_utc,
p.paid_date_utc as payment_paid_date_utc,
p.payment_reference,
-- Same comment regarding Due Date + At the moment, Guest Products are not
-- refundable, but these could be in the future
p.refunded_at_utc as refund_due_at_utc,
p.refunded_date_utc as refund_due_date_utc,
p.refunded_at_utc as payment_refunded_at_utc,
p.refunded_date_utc as payment_refunded_date_utc,
p.refund_payment_reference,
vr.id_user_host as id_user_host,
vr.id_user_guest as id_user_guest,
vrtgp.id_verification_request,
gp.guest_product_name,
'GUEST_PRODUCT_PAYMENT' as guest_product_payment_source,
p.currency,
p.amount as total_amount_in_txn_currency,
p.amount * r.rate as total_amount_in_gbp,
upper(coalesce(ps.payment_status, 'UNKNOWN')) as payment_status,
p.notes
from stg_core__verification_request_guest_product_to_payment vrgptp
left join stg_core__payment p on vrgptp.id_payment = p.id_payment
inner join
stg_core__payment_status ps on p.id_payment_status = ps.id_payment_status
inner join
int_simple_exchange_rates r
-- Note that the following conversion is made on Paid date, not Due Date,
-- as Due Date does not make sense for Guest Products
on p.paid_date_utc = r.rate_date_utc
and p.currency = r.from_currency
and r.to_currency = 'GBP'
left join
stg_core__verification_request_to_guest_product vrtgp
on vrgptp.id_verification_request_to_guest_product
= vrtgp.id_verification_request_to_guest_product
left join
int_core__guest_products gp on vrtgp.id_guest_product = gp.id_guest_product
left join
stg_core__verification_request vr
on vrtgp.id_verification_request = vr.id_verification_request
)
select *
from guest_product_payments_from_verification_flow
union all
select *
from guest_product_payments_from_guest_product_flow

View file

@ -5798,6 +5798,7 @@ models:
- not_null
- name: int_core__guest_product_payments
latest_version: 1
description: |
A model that holds guest products payments with details around
when they happen, what service was being paid, what was the related
@ -5809,6 +5810,12 @@ models:
(!) At this moment, this model only includes Check In Cover payments made
as Verification Payments.
versions:
- v: 1
- v: 2
columns:
- include: all
columns:
- name: id_guest_product_payment
data_type: text