Merged PR 4263: Payments model for legacy report

# Description

Payments model for legacy report
It includes payments with and without taxes for guest payment validations.
It also has the payaway amount depending on whether the host or superhog is taking the risk.

# 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.

In case you want to take a look at how is it looking

![image.png](https://guardhog.visualstudio.com/4148d95f-4b6d-4205-bcff-e9c8e0d2ca65/_apis/git/repositories/54ac356f-aad7-46d2-b62c-e8c5b3bb8ebf/pullRequests/4263/attachments/image.png)

Payments model for legacy report

Related work items: #27178
This commit is contained in:
Joaquin Ossa 2025-02-11 11:14:23 +00:00
commit c4a6a78bd5
7 changed files with 832 additions and 1 deletions

View file

@ -73,7 +73,7 @@ select
uh.company_name,
b.guest_first_name,
b.guest_last_name,
b.guest_email,
uu.guest_email,
uu.billing_country_name as guest_billing_country,
uu.billing_town as guest_billing_town,
a.friendly_name,

View file

@ -0,0 +1,67 @@
with
int_core__verification_payments as (
select * from {{ ref("int_core__verification_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") }}),
int_core__bookings as (select * from {{ ref("int_core__bookings") }}),
int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}),
int_daily_currency_exchange_rates as (
select * from {{ ref("int_daily_currency_exchange_rates") }}
)
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,
der.rate as exchange_rate_to_gbp,
uh.id_user_host,
uh.id_deal,
uh.first_name as host_first_name,
uh.last_name as host_last_name,
uh.email as host_email,
uh.company_name,
uh.billing_country_name as host_country,
b.guest_first_name,
b.guest_last_name,
uu.email as guest_email,
uu.billing_country_name as guest_billing_country,
uu.billing_town as guest_billing_town,
a.friendly_name,
a.address_line_1,
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
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_daily_currency_exchange_rates der
on vp.payment_paid_date_utc = der.rate_date_utc
and der.from_currency = vp.currency
and der.to_currency = 'GBP'

View file

@ -21,6 +21,7 @@ with
int_core__payaway_per_month_user as (
select * from {{ ref("int_core__payaway_per_month_user") }}
),
int_core__waiver_fees as (select * from {{ ref("int_core__waiver_fees") }}),
not_taxed_vat_details as (
-- This CTE contains the logic that applies to payments that are not
-- subject to VAT.
@ -203,6 +204,9 @@ select
vtp.id_verification,
v.id_verification_request,
vpt.verification_payment_type,
wf.is_host_taking_waiver_risk,
wf.payaway_percentage,
wf.payaway_minimum_commission_local_curr,
p.currency,
p.amount as total_amount_in_txn_currency,
(p.amount * r.rate)::decimal(19, 4) as total_amount_in_gbp,
@ -238,6 +242,22 @@ select
vat.vat_rate,
vat.is_service_subject_to_vat,
vat.is_vat_taxed,
wf.amount_due_to_host_in_txn_currency,
(wf.amount_due_to_host_in_txn_currency / (1 + vat.vat_rate))::decimal(
19, 4
) as amount_due_to_host_without_taxes_in_txn_currency,
wf.amount_due_to_host_in_gbp,
(wf.amount_due_to_host_in_gbp / (1 + vat.vat_rate))::decimal(
19, 4
) as amount_due_to_host_without_taxes_in_gbp,
wf.superhog_fee_in_txn_currency,
(wf.superhog_fee_in_txn_currency / (1 + vat.vat_rate))::decimal(
19, 4
) as superhog_fee_without_taxes_in_txn_currency,
wf.superhog_fee_in_gbp,
(wf.superhog_fee_in_txn_currency / (1 + vat.vat_rate))::decimal(
19, 4
) as superhog_fee_without_taxes_in_gbp,
vat.is_missing_user_country,
vat.are_user_details_deleted,
vat.is_missing_vat_rate_for_country,
@ -271,3 +291,4 @@ left join
from not_taxed_vat_details
) as vat
on vat.id_verification_to_payment = vtp.id_verification_to_payment
left join int_core__waiver_fees wf on vtp.id_payment = wf.id_payment

View file

@ -0,0 +1,105 @@
-- Model to obtain amount due to host and superhog fee.
-- This depends on their payaway plan at the moment of the payment.
-- If they don't have a payaway plan, then superhog is taking the risk.
-- For more details on the calculation, please refer to the documentation.
-- https://www.notion.so/truvi/Guest-Services-Taxes-How-to-calculate-a5ab4c049d61427fafab669dbbffb3a2?pvs=4
with
stg_core__verification_to_payment as (
select * from {{ ref("stg_core__verification_to_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") }}),
stg_core__verification_request as (
select * from {{ ref("stg_core__verification_request") }}
),
stg_core__payment as (select * from {{ ref("stg_core__payment") }}),
int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }}),
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
stg_seed__guest_services_vat_rates_by_country as (
select * from {{ ref("stg_seed__guest_services_vat_rates_by_country") }}
),
int_core__payaway as (select * from {{ ref("int_core__payaway") }})
select
vtp.id_payment,
uu.billing_country_iso_3,
pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr
* cer.rate as payaway_minimum_commission_local_curr,
case
when pa.id_payaway_plan is not null then true else false
end as is_host_taking_waiver_risk,
case
when pa.id_payaway_plan is not null
then
p.amount - greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
else 0
end as amount_due_to_host_in_txn_currency,
case
when pa.id_payaway_plan is not null
then
(
p.amount - greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
)
* ser.rate
else 0
end as amount_due_to_host_in_gbp,
case
when pa.id_payaway_plan is not null
then
greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
else p.amount
end as superhog_fee_in_txn_currency,
case
when pa.id_payaway_plan is not null
then
(
greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
)
* ser.rate
else p.amount
end as superhog_fee_in_gbp
from stg_core__verification_to_payment vtp
left join stg_core__payment p on vtp.id_payment = p.id_payment
left join stg_core__verification v on vtp.id_verification = v.id_verification
left join
stg_core__verification_payment_type vpt
on vtp.id_verification_payment_type = vpt.id_verification_payment_type
left join
stg_core__verification_request vr
on v.id_verification_request = vr.id_verification_request
left join
int_core__payaway pa
on vr.id_user_host = pa.id_user_host
and p.paid_at_utc
between pa.start_at_utc and coalesce(pa.end_at_utc, {{ var("end_of_time") }})
left join
int_simple_exchange_rates ser
on p.paid_date_utc = ser.rate_date_utc
and ser.from_currency = p.currency
and ser.to_currency = 'GBP'
left join int_core__unified_user uu on vr.id_user_host = uu.id_user
-- We need to exchange the minimum payaway commissions from host currency
-- to currency used by guest in the payment.
left join
int_simple_exchange_rates cer
on p.paid_date_utc = cer.rate_date_utc
and cer.from_currency = uu.account_currency_iso4217
and cer.to_currency = p.currency
left join
stg_seed__guest_services_vat_rates_by_country vat
on uu.billing_country_iso_3 = vat.alpha_3
where upper(vpt.verification_payment_type) = 'WAIVER'

View file

@ -768,6 +768,23 @@ models:
versions:
- v: 2
columns:
- name: is_host_taking_waiver_risk
data_type: boolean
description: Boolean indicating whether the host is taking the risk
- name: payaway_percentage
data_type: numeric
description: Percentage of the payment that goes to Superhog.
data_tests:
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
max_value: 0.99
strictly: false
- name: payaway_minimum_commission_local_curr
data_type: numeric
description: Minimum commission amount in local currency.
- name: total_amount_in_txn_currency
data_type: numeric
description: |
@ -859,6 +876,46 @@ models:
data_tests:
- not_null
- name: amount_due_to_host_in_txn_currency
data_type: numeric
description: |
The amount payable to the host with taxes, in local currency.
- name: amount_due_to_host_in_gbp
data_type: numeric
description: |
The amount payable to the host with taxes, in GBP.
- name: amount_due_to_host_without_taxes_in_txn_currency
data_type: numeric
description: |
The amount payable to the host without taxes, in local currency.
- name: amount_due_to_host_without_taxes_in_gbp
data_type: numeric
description: |
The amount payable to the host without taxes, in GBP.
- name: superhog_fee_in_txn_currency
data_type: numeric
description: |
The service fee charged by Superhog with taxes, in local currency.
- name: superhog_fee_in_gbp
data_type: numeric
description: |
The service fee charged by Superhog with taxes, in GBP.
- name: superhog_fee_without_taxes_in_txn_currency
data_type: numeric
description: |
The service fee charged by Superhog without taxes, in local currency.
- name: superhog_fee_without_taxes_in_gbp
data_type: numeric
description: |
The service fee charged by Superhog without taxes, in GBP.
- name: is_missing_user_country
data_type: boolean
description: |
@ -5245,3 +5302,293 @@ models:
description:
"Number of bookings that have a bundle that considers this service and
are flagged."
- name: int_core__payments
description: |
A table holding payment details for guest journeys, including amounts in both
transaction currency and GBP, host and guest information, and payment status.
Currency conversions are done using using data from xexe.com.
columns:
- name: id_payment
data_type: bigint
description: Unique identifier for the payment.
data_tests:
- not_null
- name: payment_reference
data_type: character varying
description: Unique reference code associated with the payment.
- name: verification_payment_type
data_type: character varying
description: Type of payment verification, categorizing the transaction.
data_tests:
- accepted_values:
values:
- "Waiver"
- "Deposit"
- "CheckInCover"
- "Fee"
- name: is_host_taking_waiver_risk
data_type: boolean
description: Boolean indicating whether the host is taking the risk
- name: payaway_percentage
data_type: numeric
description: Percentage of the payment that goes to Superhog.
- name: payaway_minimum_commission_local_curr
data_type: numeric
description: Minimum commission amount in local currency.
- name: payment_status
data_type: character varying
description: Current status of the payment (e.g., pending, paid, refunded).
- name: payment_due_date_utc
data_type: date
description: The due date for the payment, in UTC.
- name: payment_paid_date_utc
data_type: date
description: The date when the payment was successfully made, in UTC.
- name: refund_payment_reference
data_type: date
description: The reference code associated with the refund payment.
- name: refund_due_date_utc
data_type: date
description: The due date for the refund payment, in UTC.
- name: payment_refunded_date_utc
data_type: date
description: The date when the payment was refunded, in UTC.
- name: total_amount_in_txn_currency
data_type: numeric
description: |
The total amount of the payment in local currency.
This includes taxes if applicable.
data_tests:
- not_null
- name: total_amount_in_gbp
data_type: numeric
description: |
The total amount of the payment in GBP.
This includes taxes if applicable.
data_tests:
- not_null
- name: amount_without_taxes_in_txn_currency
data_type: numeric
description: |
The net amount of the payment without taxes, in local currency.
data_tests:
- not_null
- name: amount_without_taxes_in_gbp
data_type: numeric
description: |
The net amount of the payment without taxes, in GBP.
data_tests:
- not_null
- name: tax_amount_in_txn_currency
data_type: numeric
description: |
The tax portion of the payment, in local currency.
Will be 0 if no taxes apply.
data_tests:
- not_null
- name: tax_amount_in_gbp
data_type: numeric
description: |
The tax portion of the payment, in GBP. Will be 0 if no
taxes apply.
data_tests:
- not_null
- name: amount_due_to_host_in_txn_currency
data_type: numeric
description: |
The amount payable to the host with taxes, in local currency.
- name: amount_due_to_host_in_gbp
data_type: numeric
description: |
The amount payable to the host with taxes, in GBP.
- name: amount_due_to_host_without_taxes_in_txn_currency
data_type: numeric
description: |
The amount payable to the host without taxes, in local currency.
- name: amount_due_to_host_without_taxes_in_gbp
data_type: numeric
description: |
The amount payable to the host without taxes, in GBP.
- name: superhog_fee_in_txn_currency
data_type: numeric
description: |
The service fee charged by Superhog with taxes, in local currency.
- name: superhog_fee_in_gbp
data_type: numeric
description: |
The service fee charged by Superhog with taxes, in GBP.
- name: superhog_fee_without_taxes_in_txn_currency
data_type: numeric
description: |
The service fee charged by Superhog without taxes, in local currency.
- name: superhog_fee_without_taxes_in_gbp
data_type: numeric
description: |
The service fee charged by Superhog without taxes, in GBP.
- name: currency
data_type: text
description: |
The ISO 4217 currency code (e.g., GBP, USD, EUR) in which the payment
was originally made.
- name: exchange_rate_to_gbp
data_type: numeric
description: |
The exchange rate used to convert the payment amount from local currency
to GBP.
- name: id_user_host
data_type: character varying
description: |
The unique identifier of the host receiving the payment.
- name: id_deal
data_type: character varying
description: |
Main identifier of the B2B clients. A Deal can have multiple Hosts.
A Host can have only 1 Deal or no Deal at all. This field can be null.
- name: host_first_name
data_type: character varying
description: First name of the host receiving the payment.
- name: host_last_name
data_type: character varying
description: Last name of the host receiving the payment.
- name: host_email
data_type: character varying
description: Email address of the host receiving the payment.
- name: company_name
data_type: character varying
description: |
The company name of the host.
- name: host_country
data_type: character varying
description: |
The country name of the host.
- name: guest_first_name
data_type: character varying
description: First name of the guest making the payment.
- name: guest_last_name
data_type: character varying
description: Last name of the guest making the payment.
- name: guest_email
data_type: character varying
description: Email address of the guest making the payment.
- name: guest_billing_country
data_type: text
description: |
The country name of the guest's billing address.
- name: guest_billing_town
data_type: text
description: |
The town or city name of the guest's billing address.
- name: friendly_name
data_type: character varying
description: |
A user-friendly name for the booking or transaction, often used for
display purposes.
- name: address_line_1
data_type: character varying
description: |
The first line of the property address associated with the payment.
- name: check_in_date_utc
data_type: date
description: The scheduled check-in date of the guest, in UTC.
- name: check_out_date_utc
data_type: date
description: The scheduled check-out date of the guest, in UTC.
- name: host_currency
data_type: character varying
description: |
The currency in which the host receives their payment (may differ from
the transaction currency).
- name: int_core__waiver_fees
description: |
"This model contains the fees charged for the Waiver service. It includes
the percentage of the payment that goes to Superhog, the minimum fee around
the amount charged in both local currency and GBP"
columns:
- name: id_payment
data_type: bigint
description: Unique identifier for the payment.
data_tests:
- not_null
- name: payaway_percentage
data_type: numeric
description: Percentage of the payment that goes to Superhog.
data_tests:
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
max_value: 0.99
strictly: false
- name: payaway_minimum_commission_local_curr
data_type: numeric
description: Minimum commission amount in local currency.
- name: is_host_taking_waiver_risk
data_type: boolean
description: Boolean indicating whether the host is taking the risk
- name: amount_due_to_host_in_txn_currency
data_type: numeric
description: |
The amount payable to the host with taxes, in local currency.
- name: amount_due_to_host_in_gbp
data_type: numeric
description: |
The amount payable to the host with taxes, in GBP.
- name: superhog_fee_in_txn_currency
data_type: numeric
description: |
The service fee charged by Superhog with taxes, in local currency.
- name: superhog_fee_in_gbp
data_type: numeric
description: |
The service fee charged by Superhog with taxes, in GBP.