Merged PR 5182: First version of Guest Journey Payments

# Description

Creates a first version of Guest Journey Payments. This model intends to replace int_core__verification_payments, and equivalent audit succeeds.

Additional changes:
* Removed decimal conversion in source models. In the GJ Payment model I avoid doing any currency conversion (thus one less join); however we need to have all decimals to exactly replicate the same computation. Peanuts, but still.
* Tagged as deprecated: int_core__verification_payments
* Added additional fields for reference in terms of IDs and specifically a handy is_status_paid for future joins.
* Added more robust test coverage and enhanced descriptions of fields.

# 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:
Oriol Roqué Paniagua 2025-05-12 09:25:54 +00:00
parent 77c3a02466
commit b1faa83156
4 changed files with 882 additions and 2 deletions

View file

@ -0,0 +1,348 @@
{{ config(materialized="table") }}
with
int_core__verification_product_payments as (
select * from {{ ref("int_core__verification_product_payments") }}
),
int_core__guest_product_payments as (
select * from {{ ref("int_core__guest_product_payments") }}
),
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_per_month_user as (
select * from {{ ref("int_core__payaway_per_month_user") }}
),
unified_guest_journey_payments as (
select
-- Creates a new ID with a vpp prefix (Verification Product Payment)
'vpp_' || cast(
id_verification_product_payment as text
) as id_guest_journey_payment,
'VERIFICATION_PRODUCT' as guest_journey_product_type,
verification_product_name as product_name,
id_verification_product_payment,
null as id_guest_product_payment,
id_payment,
id_verification_request,
is_refundable,
created_at_utc,
updated_at_utc,
payment_due_at_utc,
payment_due_date_utc,
payment_paid_at_utc,
payment_paid_date_utc,
payment_reference,
payment_status,
refund_due_at_utc,
refund_due_date_utc,
payment_refunded_at_utc,
payment_refunded_date_utc,
refund_payment_reference,
id_user_host,
id_user_guest,
currency,
total_amount_in_txn_currency,
total_amount_in_gbp,
is_host_taking_waiver_risk,
payaway_percentage,
payaway_minimum_commission_in_txn_currency,
amount_due_to_host_in_txn_currency,
amount_due_to_host_in_gbp,
superhog_fee_in_txn_currency,
superhog_fee_in_gbp,
notes
from int_core__verification_product_payments
union all
select
-- Creates a new ID with a gpp prefix (Guest Product Payment)
'gpp_'
|| cast(id_guest_product_payment as text) as id_guest_journey_payment,
'GUEST_PRODUCT' as guest_journey_product_type,
guest_product_name as product_name,
null as id_verification_product_payment,
id_guest_product_payment,
id_payment,
id_verification_request,
is_refundable,
created_at_utc,
updated_at_utc,
payment_due_at_utc,
payment_due_date_utc,
payment_paid_at_utc,
payment_paid_date_utc,
payment_reference,
payment_status,
refund_due_at_utc,
refund_due_date_utc,
payment_refunded_at_utc,
payment_refunded_date_utc,
refund_payment_reference,
id_user_host,
id_user_guest,
currency,
total_amount_in_txn_currency,
total_amount_in_gbp,
null as is_host_taking_waiver_risk,
null as payaway_percentage,
null as payaway_minimum_commission_in_txn_currency,
null as amount_due_to_host_in_txn_currency,
null as amount_due_to_host_in_gbp,
null as superhog_fee_in_txn_currency,
null as superhog_fee_in_gbp,
notes
from int_core__guest_product_payments
),
not_taxed_vat_details as (
-- This CTE contains the logic that applies to payments that are not
-- subject to VAT.
select
ugjp.id_guest_journey_payment,
0 as vat_rate,
false as is_service_subject_to_vat,
false as is_vat_taxed,
(gu.billing_country_iso_3 is null) as is_missing_user_country,
(
gu.billing_country_iso_3 is not null and vat.alpha_3 is null
) as is_missing_vat_rate_for_country,
(gu.is_deleted = true) as are_user_details_deleted,
-- This final case isolates null VAT rates that are not caused
-- by the previous columns. The idea is: if any of the previous
-- have happened, that's ok because there are known exceptions.
-- But if the VAT rate is missing and it's not for any of those
-- reasons, we have some unhandled issue.
case
when gu.billing_country_iso_3 is null
then false
when gu.is_deleted = true
then false
when gu.billing_country_iso_3 is not null and vat.alpha_3 is null
then false
when vat.vat_rate is null
then true
else false
end as is_missing_vat_details_without_known_cause
from unified_guest_journey_payments ugjp
left join int_core__unified_user gu on ugjp.id_user_guest = gu.id_user
left join
staging.stg_seed__guest_services_vat_rates_by_country vat
on gu.billing_country_iso_3 = vat.alpha_3
where
-- Current logic is anything that's not in the list below is not taxed.
ugjp.product_name not in ('WAIVER', 'FEE', 'CHECKINCOVER')
),
guest_driven_vat_details as (
-- This CTE contains the logic that applies to services where VAT rate
-- is determined by the guest's country.
select
ugjp.id_guest_journey_payment,
coalesce(vat.vat_rate, 0) as vat_rate,
true as is_service_subject_to_vat,
case
when vat.vat_rate = 0
then false
when gu.billing_country_iso_3 is null
then false
when vat.vat_rate < 1 and vat.vat_rate > 0
then true
else false
end as is_vat_taxed,
(gu.billing_country_iso_3 is null) as is_missing_user_country,
(
gu.billing_country_iso_3 is not null and vat.alpha_3 is null
) as is_missing_vat_rate_for_country,
(gu.is_deleted = true) as are_user_details_deleted,
-- This final case isolates null VAT rates that are not caused
-- by the previous columns. The idea is: if any of the previous
-- have happened, that's ok because there are known exceptions.
-- But if the VAT rate is missing and it's not for any of those
-- reasons, we have some unhandled issue.
case
when gu.billing_country_iso_3 is null
then false
when gu.is_deleted = true
then false
when gu.billing_country_iso_3 is not null and vat.alpha_3 is null
then false
when vat.vat_rate is null
then true
else false
end as is_missing_vat_details_without_known_cause
from unified_guest_journey_payments ugjp
left join int_core__unified_user gu on ugjp.id_user_guest = gu.id_user
left join
stg_seed__guest_services_vat_rates_by_country vat
on gu.billing_country_iso_3 = vat.alpha_3
left join
int_core__payaway_per_month_user pamu
on ugjp.id_user_host = pamu.id_user_host
and ugjp.payment_due_at_utc
between pamu.active_in_month_start_date_utc and active_in_month_end_date_utc
where
(ugjp.product_name = 'WAIVER' and pamu.id_payaway_plan is null)
or ugjp.product_name = 'CHECKINCOVER'
or ugjp.product_name = 'FEE'
),
host_driven_vat_details as (
-- This CTE contains the logic that applies to services where VAT rate
-- is determined by the host's country.
select
ugjp.id_guest_journey_payment,
case
when hu.billing_country_iso_3 = 'GBR' then vat.vat_rate else 0 -- Taxes only applicable for UK hosts
end as vat_rate,
true as is_service_subject_to_vat,
case
when hu.billing_country_iso_3 = 'GBR' then true else false
end as is_vat_taxed,
(hu.billing_country_iso_3 is null) as is_missing_user_country,
(
hu.billing_country_iso_3 is not null and vat.alpha_3 is null
) as is_missing_vat_rate_for_country,
(hu.is_deleted = true) as are_user_details_deleted,
-- This final case isolates null VAT rates that are not caused
-- by the previous columns. The idea is: if any of the previous
-- have happened, that's ok because there are known exceptions.
-- But if the VAT rate is missing and it's not for any of those
-- reasons, we have some unhandled issue.
case
when hu.billing_country_iso_3 is null
then false
when hu.is_deleted = true
then false
when hu.billing_country_iso_3 is not null and vat.alpha_3 is null
then false
when vat.vat_rate is null
then true
else false
end as is_missing_vat_details_without_known_cause
from unified_guest_journey_payments ugjp
left join int_core__unified_user hu on ugjp.id_user_host = hu.id_user
left join
stg_seed__guest_services_vat_rates_by_country vat
on hu.billing_country_iso_3 = vat.alpha_3
left join
int_core__payaway_per_month_user pamu
on ugjp.id_user_host = pamu.id_user_host
and ugjp.payment_due_at_utc
between pamu.active_in_month_start_date_utc and active_in_month_end_date_utc
where ugjp.product_name = 'WAIVER' and pamu.id_payaway_plan is not null
),
unified_vat_conditions as (
select *
from guest_driven_vat_details
union all
select *
from host_driven_vat_details
union all
select *
from not_taxed_vat_details
)
select
ugjp.id_guest_journey_payment,
ugjp.guest_journey_product_type,
ugjp.product_name,
ugjp.id_verification_product_payment,
ugjp.id_guest_product_payment,
ugjp.id_verification_request,
ugjp.id_payment,
ugjp.is_refundable,
ugjp.created_at_utc,
ugjp.updated_at_utc,
ugjp.payment_due_at_utc,
ugjp.payment_due_date_utc,
ugjp.payment_paid_at_utc,
ugjp.payment_paid_date_utc,
ugjp.payment_reference,
ugjp.payment_status,
ugjp.refund_due_at_utc,
ugjp.refund_due_date_utc,
ugjp.payment_refunded_at_utc,
ugjp.payment_refunded_date_utc,
ugjp.refund_payment_reference,
ugjp.id_user_host,
ugjp.id_user_guest,
ugjp.currency,
ugjp.total_amount_in_txn_currency::decimal(19, 4) as total_amount_in_txn_currency,
ugjp.total_amount_in_gbp::decimal(19, 4) as total_amount_in_gbp,
/*
Helping comment for logic below.
Given that guest payments are tax inclusive, the tax (column
tax_amount_in_txn_currency) is calculated as:
paid by guest
tax = paid by guest - ( ------------- )
1 + VAT Rate
The amount without tax (column amount_without_taxes_in_txn_currency) gets
calculated as:
paid by guest
amount without tax = ( ------------- )
1 + VAT Rate
*/
(
(
ugjp.total_amount_in_txn_currency
- (ugjp.total_amount_in_txn_currency / (1 + vat.vat_rate))
)
* vat.is_service_subject_to_vat::int -- Multiplying by this makes amount 0 if not taxable
)::decimal(19, 4) as tax_amount_in_txn_currency,
(
(ugjp.total_amount_in_gbp - (ugjp.total_amount_in_gbp / (1 + vat.vat_rate)))
* vat.is_service_subject_to_vat::int
)::decimal(19, 4) as tax_amount_in_gbp,
(ugjp.total_amount_in_txn_currency / (1 + vat.vat_rate))::decimal(
19, 4
) as amount_without_taxes_in_txn_currency,
((ugjp.total_amount_in_gbp / (1 + vat.vat_rate)))::decimal(
19, 4
) as amount_without_taxes_in_gbp,
-- Host Revenue Share details --
ugjp.is_host_taking_waiver_risk,
ugjp.payaway_percentage,
ugjp.payaway_minimum_commission_in_txn_currency,
ugjp.amount_due_to_host_in_txn_currency,
(ugjp.amount_due_to_host_in_txn_currency / (1 + vat.vat_rate))::decimal(
19, 4
) as amount_due_to_host_without_taxes_in_txn_currency,
ugjp.amount_due_to_host_in_gbp,
(ugjp.amount_due_to_host_in_gbp / (1 + vat.vat_rate))::decimal(
19, 4
) as amount_due_to_host_without_taxes_in_gbp,
ugjp.superhog_fee_in_txn_currency,
(ugjp.superhog_fee_in_txn_currency / (1 + vat.vat_rate))::decimal(
19, 4
) as superhog_fee_without_taxes_in_txn_currency,
ugjp.superhog_fee_in_gbp,
(ugjp.superhog_fee_in_gbp / (1 + vat.vat_rate))::decimal(
19, 4
) as superhog_fee_without_taxes_in_gbp,
-- VAT Details --
vat.vat_rate,
vat.is_service_subject_to_vat,
vat.is_vat_taxed,
vat.is_missing_user_country,
vat.are_user_details_deleted,
vat.is_missing_vat_rate_for_country,
vat.is_missing_vat_details_without_known_cause,
ugjp.notes,
case
when ugjp.payment_status = {{ var("paid_payment_state") }} then true else false
end as is_paid_status
from unified_guest_journey_payments ugjp
left join
(
select *
from guest_driven_vat_details
union all
select *
from host_driven_vat_details
union all
select *
from not_taxed_vat_details
) as vat
on vat.id_guest_journey_payment = ugjp.id_guest_journey_payment

View file

@ -41,7 +41,7 @@ with
'VERIFICATION_PAYMENT' as guest_product_payment_source,
p.currency,
p.amount as total_amount_in_txn_currency,
(p.amount * r.rate)::decimal(19, 4) as total_amount_in_gbp,
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

View file

@ -45,7 +45,7 @@ select
) as verification_product_name,
p.currency,
p.amount as total_amount_in_txn_currency,
(p.amount * r.rate)::decimal(19, 4) as total_amount_in_gbp,
p.amount * r.rate as total_amount_in_gbp,
wf.is_host_taking_waiver_risk,
wf.payaway_percentage,
-- The currency available in Waiver Fees model is in the actual transaction

View file

@ -670,6 +670,7 @@ models:
date before a starting date.
- name: int_core__verification_payments
deprecation_date: 2025-05-15 08:00:00
latest_version: 2
description: >-
A simplified table that holds guest journey payments with details around
@ -6556,3 +6557,534 @@ models:
description: |
Notes or comments associated with the payment.
It can be null if there are no notes.
- name: int_core__guest_journey_payments
description: |
A model that provides all payments that go through a Guest Journey.
This model unifies both Verification Product Payments (Waiver, Deposit)
and Guest Product Payments (Check In Cover, etc).
The different amounts are available in the transaction currency (the currency
used by the guest to pay) and in GBP. Additionally, this model provides tax
logic computation to convert amounts with taxes to amounts without taxes.
You can find out more about Guest Tax calculation here:
https://www.notion.so/knowyourguest-superhog/Guest-Services-Taxes-How-to-calculate-a5ab4c049d61427fafab669dbbffb3a2?pvs=4
columns:
- name: id_guest_journey_payment
data_type: text
description: |
Unique identifier for the guest journey payment.
It's a built-in unique ID that means nothing outside DWH.
It combines the id_verification_product_payment and the
id_guest_journey_payment into a unique ID by adding the prefix
gpp for Guest Product Payments and vpp for Verification Product
Payments.
data_tests:
- unique
- not_null
- name: guest_journey_product_type
data_type: text
description: |
Type of the product, either GUEST_PRODUCT or
VERIFICATION_PRODUCT.
It cannot be null.
data_tests:
- not_null
- accepted_values:
values:
- GUEST_PRODUCT
- VERIFICATION_PRODUCT
- name: product_name
data_type: text
description: |
Name of the guest journey product that has a
payment.
It cannot be null. Some old historical values
might be categorised as UNKNOWN.
data_tests:
- not_null
- accepted_values:
values:
- FEE
- DEPOSIT
- WAIVER
- CHECKINCOVER
- UNKNOWN
- name: id_verification_product_payment
data_type: bigint
description: |
The ID for Verification Product Payments.
It cannot be null for Product Types equal to VERIFICATION_PRODUCT.
It's null for Product Types equal to GUEST_PRODUCT.
data_tests:
- not_null:
where: "guest_journey_product_type = 'VERIFICATION_PRODUCT'"
- is_null:
where: "guest_journey_product_type = 'GUEST_PRODUCT'"
- name: id_guest_product_payment
data_type: bigint
description: |
The ID for Guest Product Payments.
It cannot be null for Product Types equal to GUEST_PRODUCT.
It's null for Product Types equal to VERIFICATION_PRODUCT.
data_tests:
- not_null:
where: "guest_journey_product_type = 'GUEST_PRODUCT'"
- is_null:
where: "guest_journey_product_type = 'VERIFICATION_PRODUCT'"
- name: id_payment
data_type: bigint
description: |
Unique ID for the payment itself.
data_tests:
- unique
- not_null
- name: id_verification_request
data_type: bigint
description: |
Unique identifier of the Verification Request that has a payment.
Since a Guest Journey is uniquely attributed to a single Verification
Request, this ID exists for any type of product payment.
It can be null for same-day payments due to different freshness
of the sources used to build this model.
data_tests:
- not_null:
where: "date(created_at_utc) < current_date"
- name: is_refundable
data_type: boolean
description: |
Indicates whether the payment is refundable or not.
This does NOT mean that the payment is actually refunded.
- name: created_at_utc
data_type: timestamp without time zone
description: |
Timestamp of when the payment was created.
It cannot be null.
data_tests:
- not_null
- name: updated_at_utc
data_type: timestamp without time zone
description: |
Timestamp of when the payment was last updated.
It cannot be null.
data_tests:
- not_null
- name: payment_due_at_utc
data_type: timestamp without time zone
description: |
Timestamp of when the payment is due.
It cannot be null.
data_tests:
- not_null
- name: payment_due_date_utc
data_type: date
description: |
Date of when the payment is due.
It cannot be null.
data_tests:
- not_null
- name: payment_paid_at_utc
data_type: timestamp without time zone
description: |
Timestamp of when the payment was paid.
It can be null if the payment has not been paid yet.
If the payment is in PAID status, then this field
needs to be filled.
data_tests:
- not_null:
where: "is_paid_status = True"
- name: payment_paid_date_utc
data_type: date
description: |
Date of when the payment was paid.
It can be null if the payment has not been paid yet.
If the payment is in PAID status, then this field
needs to be filled.
data_tests:
- not_null:
where: "is_paid_status = True"
- name: payment_reference
data_type: character varying
description: |
Reference code associated with the payment.
It can be null if the payment has not been paid yet.
- name: refund_due_at_utc
data_type: timestamp without time zone
description: |
Timestamp of when the refund is due.
It can be null if the payment has not been refunded.
- name: refund_due_date_utc
data_type: date
description: |
Date of when the refund is due.
It can be null if the payment has not been refunded.
- name: payment_refunded_at_utc
data_type: timestamp without time zone
description: |
Timestamp of when the payment was refunded.
It can be null if the payment has not been refunded.
- name: payment_refunded_date_utc
data_type: date
description: |
Date of when the payment was refunded.
It can be null if the payment has not been refunded.
- name: refund_payment_reference
data_type: character varying
description: |
Reference code associated with the refund payment.
It can be null if the payment has not been refunded.
- name: id_user_host
data_type: character varying
description: |
Unique identifier of the Host linked to the Verification
Request that has a payment.
It can be null for same-day payments due to different freshness
of the sources used to build this model.
data_tests:
- not_null:
where: "date(created_at_utc) < current_date"
- name: id_user_guest
data_type: character varying
description: |
Unique identifier of the Guest linked to the Verification
Request that has a payment.
It cannot be null.
data_tests:
- not_null
- name: currency
data_type: character varying
description: |
The ISO 4217 currency code (e.g., GBP, USD, EUR) in which the payment
was originally made.
It can be null for same-day payments due to different freshness
of the sources used to build this model.
data_tests:
- not_null:
where: "date(created_at_utc) < current_date"
- name: payment_status
data_type: character varying
description: |
Current status of the payment (e.g., PAID).
It cannot be null.
data_tests:
- accepted_values:
values:
- PAID
- PAID MANUALLY
- CANCELLED
- REFUNDED
- REFUND FAILED
- FAILED WITH RETRY
- FAILED
- UNKNOWN
- name: notes
data_type: character varying
description: |
Notes or comments associated with the payment.
It can be null if there are no notes.
- name: total_amount_in_txn_currency
data_type: numeric
description: |
The total amount due created by the interaction, in the currency
of the transaction.
Should we refund the payment, this is also the amount we will give
back to the guest.
data_tests:
- not_null
- name: total_amount_in_gbp
data_type: numeric
description: |
The total amount due created by the interaction, in GBP.
Should we refund the payment, this is the GBP equivalent of the
amount we will give back to the guest, but we won't be paying in
GBP unless the original payment was in GBP.
data_tests:
- not_null
- name: tax_amount_in_txn_currency
data_type: numeric
description: |
The tax amount applicable to this transaction, in the currency of
the transaction.
If the transaction accrues no taxes, will be 0.
data_tests:
- not_null
- name: tax_amount_in_gbp
data_type: numeric
description: |
The tax amount applicable to this transaction, in GBP.
If the transaction accrues no taxes, will be 0.
data_tests:
- not_null
- name: amount_without_taxes_in_txn_currency
data_type: numeric
description: |
The total amount minus taxes, in the currency of the transaction.
This is what should be considered net-of-taxes revenue for
Truvi.
If the transaction accrues no taxes, will be equal to the field
total_amount_in_txn_currency.
data_tests:
- not_null
- name: amount_without_taxes_in_gbp
data_type: numeric
description: |
The total amount minus taxes, in GBP.
This is what should be considered net-of-taxes revenue for
Truvi.
If the transaction accrues no taxes, will be equal to the field
total_amount_in_txn_currency.
data_tests:
- not_null
- name: vat_rate
data_type: numeric
description: |
The applicable VAT rate to this payment. This is inferred from (1)
which service is the payment related to and (2) what's the billing
country of the guest.
data_tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
max_value: 0.99
strictly: false
- name: is_service_subject_to_vat
data_type: boolean
description: |
Whether the related payment is subject to VAT. For instance,
deposit payments are not.
data_tests:
- not_null
- name: is_vat_taxed
data_type: boolean
description: |
Syntactic sugar to indicate if there's any VAT on this payment.
Will be true if so, false if not for any reason (guest country has
no VAT, the payment is for a deposit, etc.)
data_tests:
- not_null
- name: is_host_taking_waiver_risk
data_type: boolean
description: |
Boolean indicating whether the host is taking the risk.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: payaway_percentage
data_type: numeric
description: |
Percentage of the payment that goes to Truvi.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: payaway_minimum_commission_in_txn_currency
data_type: numeric
description: |
Minimum commission amount in the payment currency.
Note that this is converted from Host currency to the payment
currency for information purposes, but that the Host always gets
paid in its own currency.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: amount_due_to_host_in_txn_currency
data_type: numeric
description: |
The amount payable to the host in the payment currency.
Note that this is converted from Host currency to the payment
currency for information purposes, but that the Host always gets
paid in its own currency.
This includes taxes if applicable.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: amount_due_to_host_in_gbp
data_type: numeric
description: |
The amount payable to the host in GBP.
Note that this is converted from Host currency to GBP for
information purposes, but that the Host always gets paid
in its own currency.
This includes taxes if applicable.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: superhog_fee_in_txn_currency
data_type: numeric
description: |
The service fee charged by Truvi in the payment currency.
This includes taxes if applicable.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: superhog_fee_in_gbp
data_type: numeric
description: |
The service fee charged by Truvi in GBP.
This includes taxes if applicable.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: amount_due_to_host_without_taxes_in_txn_currency
data_type: numeric
description: |
The amount payable to the host in the payment currency, without taxes.
Note that this is converted from Host currency to the payment
currency for information purposes, but that the Host always gets
paid in its own currency.
If the transaction accrues no taxes, will be equal to the field
amount_due_to_host_in_txn_currency.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: amount_due_to_host_without_taxes_in_gbp
data_type: numeric
description: |
The amount payable to the host in GBP, without taxes.
Note that this is converted from Host currency to GBP for
information purposes, but that the Host always gets paid in
its own currency.
If the transaction accrues no taxes, will be equal to the field
amount_due_to_host_in_gbp.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: superhog_fee_without_taxes_in_txn_currency
data_type: numeric
description: |
The service fee charged by Truvi in the payment currency,
without taxes.
If the transaction accrues no taxes, will be equal to the field
superhog_fee_in_txn_currency.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: superhog_fee_without_taxes_in_gbp
data_type: numeric
description: |
The service fee charged by Truvi in GBP, without taxes.
If the transaction accrues no taxes, will be equal to the field
superhog_fee_in_gbp.
It is always null if the payment is not a Waiver payment.
data_tests:
- is_null:
where: "product_name <> 'WAIVER'"
- name: is_missing_user_country
data_type: boolean
description: |
True if, for some reason, the user doesn't have an informed
country.
The only known, justified reason for this is that the user was
deleted, along with the billing details.
If this turns true in any other case, you should really find out
why the guest doesn't have a billing country.
data_tests:
- not_null
- accepted_values:
values:
- false
where: (are_user_details_deleted != true and are_user_details_deleted is not null)
- name: is_missing_vat_rate_for_country
data_type: boolean
description: |
True if the user country is informed, but no VAT rates were found
for it.
This has to be a joining issue, since our database for VAT rates
covers all the countries in the world. We simply assign a 0% rate
to countries where we don't collect taxes.
If this turns true in any other case, you should really find out
what's happening.
data_tests:
- not_null
- accepted_values:
values:
- false
where: (are_user_details_deleted != true and are_user_details_deleted is not null)
- name: are_user_details_deleted
data_type: boolean
description: |
True if the user has been deleted, which is a possible explanation
for why there might be no country informed.
- name: is_missing_vat_details_without_known_cause
data_type: boolean
description: |
True if the VAT rate is missing as a fallback for any
other reason beyond the other one specified in the table.
If this turns true, you have an unhandled problem and you should
fix it.
data_tests:
- not_null
- accepted_values:
values:
- false
- name: is_paid_status
data_type: boolean
description: |
A handy boolean that just considers payments that are
currently in the PAID status. Keep in mind that if the
payment gets paid and then refunded, this boolean will
be false as status only reflects the latest transition.
data_tests:
- not_null