Merged PR 5187: Switch models that use int_core__verification_payments
# Description Switches all models that still use int_core__verification_payments, except for the equivalent in reporting that needs a parallel GJ Payments to do a proper refactor. # 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
c6b61856f0
commit
3badc02c9f
9 changed files with 132 additions and 110 deletions
|
|
@ -3,15 +3,15 @@
|
|||
materialized="table", unique_key=["id_verification_request", "ab_test_name"]
|
||||
)
|
||||
}}
|
||||
{% 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 deposit_fees_product_payment_items = "('FEE')" %}
|
||||
{% set waiver_fees_product_payment_items = "('WAIVER')" %}
|
||||
{% set checkin_cover_fees_product_payment_items = "('CHECKINCOVER')" %}
|
||||
with
|
||||
int_core__ab_test_tracking_guest_journey as (
|
||||
select * from {{ ref("int_core__ab_test_tracking_guest_journey") }}
|
||||
),
|
||||
int_core__verification_payments as (
|
||||
select * from {{ ref("int_core__verification_payments", version=2) }}
|
||||
int_core__guest_journey_payments as (
|
||||
select * from {{ ref("int_core__guest_journey_payments") }}
|
||||
),
|
||||
int_core__verification_requests as (
|
||||
select * from {{ ref("int_core__verification_requests") }}
|
||||
|
|
@ -56,58 +56,46 @@ select
|
|||
gjd.verification_started_date_utc,
|
||||
gjd.verification_completed_date_utc,
|
||||
gjd.experience_rating,
|
||||
max(vp.payment_paid_date_utc) as last_payment_paid_date_utc,
|
||||
max(gjp.payment_paid_date_utc) as last_payment_paid_date_utc,
|
||||
sum(
|
||||
case
|
||||
when
|
||||
upper(vp.verification_payment_type)
|
||||
in {{ deposit_fees_verification_payment_type_items }}
|
||||
or upper(vp.verification_payment_type)
|
||||
in {{ waiver_fees_verification_payment_type_items }}
|
||||
or upper(vp.verification_payment_type)
|
||||
in {{ checkin_cover_fees_verification_payment_type_items }}
|
||||
gjp.product_name in {{ deposit_fees_product_payment_items }}
|
||||
or gjp.product_name in {{ waiver_fees_product_payment_items }}
|
||||
or gjp.product_name in {{ checkin_cover_fees_product_payment_items }}
|
||||
then amount_without_taxes_in_gbp
|
||||
else null
|
||||
end
|
||||
) as guest_revenue_without_taxes_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when
|
||||
upper(vp.verification_payment_type)
|
||||
in {{ deposit_fees_verification_payment_type_items }}
|
||||
when gjp.product_name in {{ deposit_fees_product_payment_items }}
|
||||
then amount_without_taxes_in_gbp
|
||||
else null
|
||||
end
|
||||
) as deposit_fees_without_taxes_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when
|
||||
upper(vp.verification_payment_type)
|
||||
in {{ waiver_fees_verification_payment_type_items }}
|
||||
when gjp.product_name in {{ waiver_fees_product_payment_items }}
|
||||
then amount_without_taxes_in_gbp
|
||||
else null
|
||||
end
|
||||
) as waiver_fees_without_taxes_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when
|
||||
upper(vp.verification_payment_type)
|
||||
in {{ checkin_cover_fees_verification_payment_type_items }}
|
||||
when gjp.product_name in {{ checkin_cover_fees_product_payment_items }}
|
||||
then amount_without_taxes_in_gbp
|
||||
else null
|
||||
end
|
||||
) as check_in_cover_fees_without_taxes_in_gbp
|
||||
from guest_journey_data gjd
|
||||
left join
|
||||
int_core__verification_payments vp
|
||||
on gjd.id_verification_request = vp.id_verification_request
|
||||
and upper(vp.payment_status) = {{ var("paid_payment_state") }}
|
||||
int_core__guest_journey_payments gjp
|
||||
on gjd.id_verification_request = gjp.id_verification_request
|
||||
and gjp.is_paid_status = true
|
||||
and (
|
||||
upper(vp.verification_payment_type)
|
||||
in {{ deposit_fees_verification_payment_type_items }}
|
||||
or upper(vp.verification_payment_type)
|
||||
in {{ waiver_fees_verification_payment_type_items }}
|
||||
or upper(vp.verification_payment_type)
|
||||
in {{ checkin_cover_fees_verification_payment_type_items }}
|
||||
gjp.product_name in {{ deposit_fees_product_payment_items }}
|
||||
or gjp.product_name in {{ waiver_fees_product_payment_items }}
|
||||
or gjp.product_name in {{ checkin_cover_fees_product_payment_items }}
|
||||
)
|
||||
group by 1, 2, 3, 4, 5, 6, 7, 8
|
||||
|
|
|
|||
|
|
@ -2,7 +2,7 @@
|
|||
{% set fee = "Payment Validation: Fee" %}
|
||||
{% set deposit = "Payment Validation: FeeWithDeposit" %}
|
||||
{% set no_cover = "Payment Validation: NoCover" %}
|
||||
{% set checkin_cover = "CheckInCover" %}
|
||||
{% set checkin_cover = "CHECKINCOVER" %}
|
||||
|
||||
with
|
||||
stg_core__verification as (select * from {{ ref("stg_core__verification") }}),
|
||||
|
|
@ -13,8 +13,8 @@ with
|
|||
int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}),
|
||||
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
|
||||
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
|
||||
int_core__verification_payments as (
|
||||
select * from {{ ref("int_core__verification_payments", v="2") }}
|
||||
int_core__guest_journey_payments as (
|
||||
select * from {{ ref("int_core__guest_journey_payments") }}
|
||||
),
|
||||
payment_validation as (
|
||||
select
|
||||
|
|
@ -49,10 +49,10 @@ with
|
|||
case
|
||||
when total_amount_in_txn_currency is not null then true else false
|
||||
end as chose_checkin_cover
|
||||
from int_core__verification_payments
|
||||
from int_core__guest_journey_payments
|
||||
where
|
||||
verification_payment_type = '{{ checkin_cover }}'
|
||||
and payment_status in ('Paid', 'Refunded')
|
||||
product_name = '{{ checkin_cover }}'
|
||||
and payment_status in ('PAID', 'REFUNDED')
|
||||
)
|
||||
select
|
||||
b.id_booking,
|
||||
|
|
|
|||
|
|
@ -8,6 +8,7 @@ with
|
|||
int_core__booking_to_service as (
|
||||
select * from {{ ref("int_core__booking_to_service") }}
|
||||
),
|
||||
stg_core__verification as (select * from {{ ref("stg_core__verification") }}),
|
||||
stg_core__product_service as (select * from {{ ref("stg_core__product_service") }}),
|
||||
stg_core__protection_plan as (select * from {{ ref("stg_core__protection_plan") }}),
|
||||
int_core__product_service_to_price as (
|
||||
|
|
@ -23,8 +24,8 @@ with
|
|||
select * from {{ ref("int_core__protection_plan_billing_item") }}
|
||||
),
|
||||
int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }}),
|
||||
int_core__verification_payments as (
|
||||
select * from {{ ref("int_core__verification_payments", version = 2) }}
|
||||
int_core__guest_journey_payments as (
|
||||
select * from {{ ref("int_core__guest_journey_payments") }}
|
||||
),
|
||||
product_service_billing_aggregation as (
|
||||
select
|
||||
|
|
@ -63,19 +64,27 @@ with
|
|||
select
|
||||
bts.id_booking,
|
||||
bts.id_product_service,
|
||||
vp.currency as currency_code,
|
||||
sum(vp.amount_without_taxes_in_txn_currency) as service_total_price_in_local_currency,
|
||||
sum(vp.amount_without_taxes_in_gbp) as service_total_price_in_gbp,
|
||||
min(vp.payment_paid_date_utc) as first_chargeable_date_utc,
|
||||
max(vp.payment_paid_date_utc) as last_chargeable_date_utc
|
||||
gjp.currency as currency_code,
|
||||
sum(gjp.amount_without_taxes_in_txn_currency) as service_total_price_in_local_currency,
|
||||
sum(gjp.amount_without_taxes_in_gbp) as service_total_price_in_gbp,
|
||||
min(gjp.payment_paid_date_utc) as first_chargeable_date_utc,
|
||||
max(gjp.payment_paid_date_utc) as last_chargeable_date_utc
|
||||
from int_core__booking_to_service bts
|
||||
inner join
|
||||
int_core__verification_payments vp
|
||||
on bts.id_verification = vp.id_verification
|
||||
-- We only consider 1) cases in which verification is informed and 2) payments that are paid
|
||||
stg_core__verification v
|
||||
on
|
||||
bts.id_verification = v.id_verification
|
||||
inner join
|
||||
int_core__guest_journey_payments gjp
|
||||
on
|
||||
v.id_verification_request = gjp.id_verification_request
|
||||
-- We only consider 1) cases in which verification is informed and
|
||||
-- 2) payments that are paid and 3) are not Guest Products, but rather
|
||||
-- Verification Products.
|
||||
where bts.id_verification is not null
|
||||
and upper(vp.payment_status) = {{ var("paid_payment_state") }}
|
||||
and bts.id_product_service is not null
|
||||
and gjp.is_paid_status
|
||||
and gjp.guest_journey_product_type = 'VERIFICATION_PRODUCT'
|
||||
group by 1, 2, 3
|
||||
),
|
||||
applied_product_services as (
|
||||
|
|
|
|||
|
|
@ -1,6 +1,6 @@
|
|||
with
|
||||
int_core__verification_payments as (
|
||||
select * from {{ ref("int_core__verification_payments", version=2) }}
|
||||
int_core__guest_journey_payments as (
|
||||
select * from {{ ref("int_core__guest_journey_payments") }}
|
||||
),
|
||||
stg_core__guest_satisfaction_responses as (
|
||||
select * from {{ ref("stg_core__guest_satisfaction_responses") }}
|
||||
|
|
@ -14,18 +14,15 @@ with
|
|||
payment_types as (
|
||||
select
|
||||
id_verification_request,
|
||||
max(
|
||||
case when verification_payment_type = 'CheckInCover' then 1 else 0 end
|
||||
)::boolean as has_check_in_cover_payment,
|
||||
max(
|
||||
case when verification_payment_type = 'Deposit' then 1 else 0 end
|
||||
)::boolean as has_deposit_payment,
|
||||
max(
|
||||
case when verification_payment_type = 'Waiver' then 1 else 0 end
|
||||
)::boolean as has_waiver_payment,
|
||||
max(case when verification_payment_type = 'Fee' then 1 else 0 end)::boolean
|
||||
max(case when product_name = 'CHECKINCOVER' then 1 else 0 end)::boolean
|
||||
as has_check_in_cover_payment,
|
||||
max(case when product_name = 'DEPOSIT' then 1 else 0 end)::boolean
|
||||
as has_deposit_payment,
|
||||
max(case when product_name = 'WAIVER' then 1 else 0 end)::boolean
|
||||
as has_waiver_payment,
|
||||
max(case when product_name = 'FEE' then 1 else 0 end)::boolean
|
||||
as has_fee_payment
|
||||
from int_core__verification_payments
|
||||
from int_core__guest_journey_payments
|
||||
group by id_verification_request
|
||||
)
|
||||
select
|
||||
|
|
|
|||
|
|
@ -1,6 +1,6 @@
|
|||
with
|
||||
int_core__verification_payments as (
|
||||
select * from {{ ref("int_core__verification_payments") }}
|
||||
int_core__guest_journey_payments as (
|
||||
select * from {{ ref("int_core__guest_journey_payments") }}
|
||||
),
|
||||
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
|
||||
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
|
||||
|
|
@ -11,35 +11,44 @@ with
|
|||
),
|
||||
int_daily_currency_exchange_rates as (
|
||||
select * from {{ ref("int_daily_currency_exchange_rates") }}
|
||||
),
|
||||
-- There's some historical cases in which a booking duplicates a verification
|
||||
-- request. The following ensures that no duplicated payment information appears.
|
||||
ranked_bookings as (
|
||||
select
|
||||
id_booking,
|
||||
id_verification_request,
|
||||
row_number() over (partition by id_verification_request) as ranking
|
||||
from int_core__bookings
|
||||
)
|
||||
select
|
||||
vp.id_payment,
|
||||
vp.payment_reference,
|
||||
vp.verification_payment_type,
|
||||
vp.is_host_taking_waiver_risk,
|
||||
vp.payaway_percentage,
|
||||
vp.payaway_minimum_commission_local_curr,
|
||||
vp.payment_status,
|
||||
vp.payment_due_date_utc,
|
||||
vp.payment_paid_date_utc,
|
||||
vp.refund_payment_reference,
|
||||
vp.refund_due_date_utc,
|
||||
vp.payment_refunded_date_utc,
|
||||
vp.total_amount_in_txn_currency,
|
||||
vp.total_amount_in_gbp,
|
||||
vp.amount_without_taxes_in_txn_currency,
|
||||
vp.amount_without_taxes_in_gbp,
|
||||
vp.tax_amount_in_txn_currency,
|
||||
vp.tax_amount_in_gbp,
|
||||
vp.amount_due_to_host_in_txn_currency,
|
||||
vp.amount_due_to_host_in_gbp,
|
||||
vp.amount_due_to_host_without_taxes_in_txn_currency,
|
||||
vp.amount_due_to_host_without_taxes_in_gbp,
|
||||
vp.superhog_fee_in_txn_currency,
|
||||
vp.superhog_fee_in_gbp,
|
||||
vp.superhog_fee_without_taxes_in_txn_currency,
|
||||
vp.superhog_fee_without_taxes_in_gbp,
|
||||
vp.currency,
|
||||
gjp.id_payment,
|
||||
gjp.payment_reference,
|
||||
gjp.product_name,
|
||||
gjp.is_host_taking_waiver_risk,
|
||||
gjp.payaway_percentage,
|
||||
gjp.payaway_minimum_commission_in_txn_currency,
|
||||
gjp.payment_status,
|
||||
gjp.payment_due_date_utc,
|
||||
gjp.payment_paid_date_utc,
|
||||
gjp.refund_payment_reference,
|
||||
gjp.refund_due_date_utc,
|
||||
gjp.payment_refunded_date_utc,
|
||||
gjp.total_amount_in_txn_currency,
|
||||
gjp.total_amount_in_gbp,
|
||||
gjp.amount_without_taxes_in_txn_currency,
|
||||
gjp.amount_without_taxes_in_gbp,
|
||||
gjp.tax_amount_in_txn_currency,
|
||||
gjp.tax_amount_in_gbp,
|
||||
gjp.amount_due_to_host_in_txn_currency,
|
||||
gjp.amount_due_to_host_in_gbp,
|
||||
gjp.amount_due_to_host_without_taxes_in_txn_currency,
|
||||
gjp.amount_due_to_host_without_taxes_in_gbp,
|
||||
gjp.superhog_fee_in_txn_currency,
|
||||
gjp.superhog_fee_in_gbp,
|
||||
gjp.superhog_fee_without_taxes_in_txn_currency,
|
||||
gjp.superhog_fee_without_taxes_in_gbp,
|
||||
gjp.currency,
|
||||
der.rate as exchange_rate_to_gbp,
|
||||
b.id_booking,
|
||||
b.booking_state,
|
||||
|
|
@ -65,16 +74,20 @@ select
|
|||
b.check_in_date_utc,
|
||||
b.check_out_date_utc,
|
||||
uh.account_currency_iso4217 as host_currency
|
||||
from int_core__verification_payments vp
|
||||
left join int_core__user_host uh on vp.id_user_host = uh.id_user_host
|
||||
left join int_core__bookings b on vp.id_verification_request = b.id_verification_request
|
||||
from int_core__guest_journey_payments gjp
|
||||
left join int_core__user_host uh on gjp.id_user_host = uh.id_user_host
|
||||
left join
|
||||
ranked_bookings rb
|
||||
on gjp.id_verification_request = rb.id_verification_request
|
||||
and rb.ranking = 1
|
||||
left join int_core__bookings b on rb.id_booking = b.id_booking
|
||||
left join int_core__unified_user uu on uu.id_user = b.id_user_guest
|
||||
left join int_core__accommodation a on b.id_accommodation = a.id_accommodation
|
||||
left join
|
||||
int_core__verification_requests vr
|
||||
on vp.id_verification_request = vr.id_verification_request
|
||||
on gjp.id_verification_request = vr.id_verification_request
|
||||
left join
|
||||
int_daily_currency_exchange_rates der
|
||||
on vp.payment_paid_date_utc = der.rate_date_utc
|
||||
and der.from_currency = vp.currency
|
||||
on gjp.payment_paid_date_utc = der.rate_date_utc
|
||||
and der.from_currency = gjp.currency
|
||||
and der.to_currency = 'GBP'
|
||||
|
|
|
|||
|
|
@ -20,10 +20,8 @@ with
|
|||
amount_without_taxes_in_txn_currency,
|
||||
total_amount_in_gbp,
|
||||
amount_without_taxes_in_gbp
|
||||
from {{ ref("dwh_dbt", "int_core__verification_payments", v="2") }}
|
||||
where
|
||||
verification_payment_type = 'CheckInCover' -- 5 is check-in cover
|
||||
and payment_status in ('Paid', 'Refunded')
|
||||
from {{ ref("int_core__guest_journey_payments") }}
|
||||
where product_name = 'CHECKINCOVER' and payment_status in ('PAID', 'REFUNDED')
|
||||
)
|
||||
select
|
||||
vr.id_verification_request,
|
||||
|
|
|
|||
|
|
@ -5406,16 +5406,17 @@ models:
|
|||
data_type: character varying
|
||||
description: Unique reference code associated with the payment.
|
||||
|
||||
- name: verification_payment_type
|
||||
- name: product_name
|
||||
data_type: character varying
|
||||
description: Type of payment verification, categorizing the transaction.
|
||||
data_tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- "Waiver"
|
||||
- "Deposit"
|
||||
- "CheckInCover"
|
||||
- "Fee"
|
||||
- "WAIVER"
|
||||
- "DEPOSIT"
|
||||
- "CHECKINCOVER"
|
||||
- "FEE"
|
||||
- "UNKNOWN"
|
||||
|
||||
- name: is_host_taking_waiver_risk
|
||||
data_type: boolean
|
||||
|
|
@ -5425,9 +5426,9 @@ models:
|
|||
data_type: numeric
|
||||
description: Percentage of the payment that goes to Superhog.
|
||||
|
||||
- name: payaway_minimum_commission_local_curr
|
||||
- name: payaway_minimum_commission_in_txn_curr
|
||||
data_type: numeric
|
||||
description: Minimum commission amount in local currency.
|
||||
description: Minimum commission amount in transaction currency.
|
||||
|
||||
- name: payment_status
|
||||
data_type: character varying
|
||||
|
|
|
|||
|
|
@ -2,11 +2,26 @@ with int_core__payments as (select * from {{ ref("int_core__payments") }})
|
|||
select
|
||||
id_payment as id_payment,
|
||||
payment_reference as payment_reference,
|
||||
verification_payment_type as verification_payment_type,
|
||||
-- Reapply original naming + Keep original field name to avoid breaking PBI
|
||||
case
|
||||
when product_name = 'CHECKINCOVER'
|
||||
then 'CheckInCover'
|
||||
when product_name = 'FEE'
|
||||
then 'Fee'
|
||||
when product_name = 'WAIVER'
|
||||
then 'Waiver'
|
||||
when product_name = 'DEPOSIT'
|
||||
then 'Deposit'
|
||||
when product_name = 'UNKNOWN'
|
||||
then null
|
||||
else product_name
|
||||
end as verification_payment_type,
|
||||
is_host_taking_waiver_risk as is_host_taking_waiver_risk,
|
||||
payaway_percentage as payaway_percentage,
|
||||
payaway_minimum_commission_local_curr as payaway_minimum_commission_local_curr,
|
||||
payment_status as payment_status,
|
||||
-- Renaming to original field name to avoid breaking PBI
|
||||
payaway_minimum_commission_in_txn_currency as payaway_minimum_commission_local_curr,
|
||||
-- Reapply original naming to avoid breaking PBI
|
||||
initcap(payment_status) as payment_status,
|
||||
payment_due_date_utc as payment_due_date_utc,
|
||||
payment_paid_date_utc as payment_paid_date_utc,
|
||||
refund_payment_reference as refund_payment_reference,
|
||||
|
|
|
|||
|
|
@ -26,7 +26,8 @@ select
|
|||
verification_end_at_utc as verification_end_at_utc,
|
||||
verification_end_date_utc as verification_end_date_utc,
|
||||
currency as currency,
|
||||
payment_status as payment_status,
|
||||
-- Reapply original naming to avoid breaking PBI
|
||||
initcap(payment_status) as payment_status,
|
||||
payment_paid_date_utc as payment_paid_date_utc,
|
||||
total_amount_in_txn_currency as total_amount_in_txn_currency,
|
||||
amount_without_taxes_in_txn_currency as amount_without_taxes_in_txn_currency,
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue