Merged PR 5191: Guest Journey Payments to reporting
# Description Guest Journey Payments to reporting. This aims to substitute core__verification_payments_v2, which is in use in the report of Guest Payments within Business Overview. In order to avoid re-doing PBI work, I already set id_guest_product_payment as text for future usage. Similarly, superhog fees are called truvi fees. # 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
3badc02c9f
commit
4cac5aefa5
4 changed files with 628 additions and 7 deletions
|
|
@ -17,7 +17,10 @@ with
|
|||
int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }}),
|
||||
guest_product_payments_from_verification_payments as (
|
||||
select
|
||||
vtp.id_verification_to_payment as id_guest_product_payment,
|
||||
-- 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.id_verification_to_payment,
|
||||
vtp.is_refundable,
|
||||
|
|
|
|||
|
|
@ -6063,9 +6063,19 @@ models:
|
|||
|
||||
columns:
|
||||
- name: id_guest_product_payment
|
||||
data_type: bigint
|
||||
data_type: text
|
||||
description: |
|
||||
Unique identifier for the guest product payment.
|
||||
It's a built-in ID that concatenates the original ID with a prefix
|
||||
depending on the source, to avoid clashes. This ID does not make
|
||||
sense outside of DWH.
|
||||
The prefix used is "leg_" for "legacy" Verification To Payment,
|
||||
which corresponds to the historical CheckInCover that were considered
|
||||
as verification payment, rather than Guest Products.
|
||||
For the Guest Product Payments that follow the usual Guest Product
|
||||
flow, no prefix is added. However, keep in mind that the field is
|
||||
in text format.
|
||||
|
||||
data_tests:
|
||||
- unique
|
||||
- not_null
|
||||
|
|
@ -6580,7 +6590,7 @@ models:
|
|||
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
|
||||
"gpp" for Guest Product Payments and "vpp" for Verification Product
|
||||
Payments.
|
||||
data_tests:
|
||||
- unique
|
||||
|
|
@ -6629,9 +6639,18 @@ models:
|
|||
where: "guest_journey_product_type = 'GUEST_PRODUCT'"
|
||||
|
||||
- name: id_guest_product_payment
|
||||
data_type: bigint
|
||||
data_type: text
|
||||
description: |
|
||||
The ID for Guest Product Payments.
|
||||
It's a built-in ID that concatenates the original ID with a prefix
|
||||
depending on the source, to avoid clashes. This ID does not make
|
||||
sense outside of DWH.
|
||||
The prefix used is "leg_" for "legacy" Verification To Payment,
|
||||
which corresponds to the historical CheckInCover that were considered
|
||||
as verification payment, rather than Guest Products.
|
||||
For the Guest Product Payments that follow the usual Guest Product
|
||||
flow, no prefix is added. However, keep in mind that the field is
|
||||
in text format.
|
||||
It cannot be null for Product Types equal to GUEST_PRODUCT.
|
||||
It's null for Product Types equal to VERIFICATION_PRODUCT.
|
||||
data_tests:
|
||||
|
|
|
|||
60
models/reporting/core/core__guest_journey_payments.sql
Normal file
60
models/reporting/core/core__guest_journey_payments.sql
Normal file
|
|
@ -0,0 +1,60 @@
|
|||
with
|
||||
int_core__guest_journey_payments as (
|
||||
select * from {{ ref("int_core__guest_journey_payments") }}
|
||||
)
|
||||
select
|
||||
id_guest_journey_payment as id_guest_journey_payment,
|
||||
guest_journey_product_type as guest_journey_product_type,
|
||||
product_name as product_name,
|
||||
id_verification_product_payment as id_verification_product_payment,
|
||||
id_guest_product_payment as id_guest_product_payment,
|
||||
id_verification_request as id_verification_request,
|
||||
id_payment as id_payment,
|
||||
is_refundable as is_refundable,
|
||||
created_at_utc as created_at_utc,
|
||||
updated_at_utc as updated_at_utc,
|
||||
payment_due_at_utc as payment_due_at_utc,
|
||||
payment_due_date_utc as payment_due_date_utc,
|
||||
payment_paid_at_utc as payment_paid_at_utc,
|
||||
payment_paid_date_utc as payment_paid_date_utc,
|
||||
payment_reference as payment_reference,
|
||||
payment_status as payment_status,
|
||||
refund_due_at_utc as refund_due_at_utc,
|
||||
refund_due_date_utc as refund_due_date_utc,
|
||||
payment_refunded_at_utc as payment_refunded_at_utc,
|
||||
payment_refunded_date_utc as payment_refunded_date_utc,
|
||||
refund_payment_reference as refund_payment_reference,
|
||||
id_user_host as id_user_host,
|
||||
id_user_guest as id_user_guest,
|
||||
currency as currency,
|
||||
total_amount_in_txn_currency as total_amount_in_txn_currency,
|
||||
total_amount_in_gbp as total_amount_in_gbp,
|
||||
tax_amount_in_txn_currency as tax_amount_in_txn_currency,
|
||||
tax_amount_in_gbp as tax_amount_in_gbp,
|
||||
amount_without_taxes_in_txn_currency as amount_without_taxes_in_txn_currency,
|
||||
amount_without_taxes_in_gbp as amount_without_taxes_in_gbp,
|
||||
is_host_taking_waiver_risk as is_host_taking_waiver_risk,
|
||||
payaway_percentage as payaway_percentage,
|
||||
payaway_minimum_commission_in_txn_currency
|
||||
as payaway_minimum_commission_in_txn_currency,
|
||||
amount_due_to_host_in_txn_currency as amount_due_to_host_in_txn_currency,
|
||||
amount_due_to_host_without_taxes_in_txn_currency
|
||||
as amount_due_to_host_without_taxes_in_txn_currency,
|
||||
amount_due_to_host_in_gbp as amount_due_to_host_in_gbp,
|
||||
amount_due_to_host_without_taxes_in_gbp as amount_due_to_host_without_taxes_in_gbp,
|
||||
superhog_fee_in_txn_currency as truvi_fee_in_txn_currency,
|
||||
superhog_fee_without_taxes_in_txn_currency
|
||||
as truvi_fee_without_taxes_in_txn_currency,
|
||||
superhog_fee_in_gbp as truvi_fee_in_gbp,
|
||||
superhog_fee_without_taxes_in_gbp as truvi_fee_without_taxes_in_gbp,
|
||||
vat_rate as vat_rate,
|
||||
is_service_subject_to_vat as is_service_subject_to_vat,
|
||||
is_vat_taxed as is_vat_taxed,
|
||||
is_missing_user_country as is_missing_user_country,
|
||||
are_user_details_deleted as are_user_details_deleted,
|
||||
is_missing_vat_rate_for_country as is_missing_vat_rate_for_country,
|
||||
is_missing_vat_details_without_known_cause
|
||||
as is_missing_vat_details_without_known_cause,
|
||||
notes as notes,
|
||||
is_paid_status as is_paid_status
|
||||
from int_core__guest_journey_payments
|
||||
|
|
@ -1237,7 +1237,7 @@ models:
|
|||
It contains only those that can accept bookings (hard
|
||||
activation - not to be confused with activity-based
|
||||
segmentation).
|
||||
|
||||
|
||||
- name: total_active_listings_with_active_product_bundle
|
||||
data_type: integer
|
||||
description: |
|
||||
|
|
@ -1265,7 +1265,7 @@ models:
|
|||
description: |
|
||||
Integer-based flag version of
|
||||
total_active_listings_with_active_product_bundle_with_paid_service.
|
||||
|
||||
|
||||
# To be deleted from here
|
||||
- name: total_listings_with_product_bundle_with_paid_service
|
||||
data_type: integer
|
||||
|
|
@ -1289,7 +1289,6 @@ models:
|
|||
description: |
|
||||
Integer-based flag version of total_listings_with_active_product_bundle_with_paid_service.
|
||||
# To be deleted until here
|
||||
|
||||
- name: total_bookings_with_product_bundle
|
||||
data_type: integer
|
||||
description: |
|
||||
|
|
@ -1968,3 +1967,543 @@ models:
|
|||
data_type: bigint
|
||||
description: |
|
||||
The number of accommodations managed by the host.
|
||||
|
||||
- name: 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: text
|
||||
description: |
|
||||
The ID for Guest Product Payments.
|
||||
It's a built-in ID that concatenates the original ID with a prefix
|
||||
depending on the source, to avoid clashes. This ID does not make
|
||||
sense outside of DWH.
|
||||
The prefix used is "leg_" for "legacy" Verification To Payment,
|
||||
which corresponds to the historical CheckInCover that were considered
|
||||
as verification payment, rather than Guest Products.
|
||||
For the Guest Product Payments that follow the usual Guest Product
|
||||
flow, no prefix is added. However, keep in mind that the field is
|
||||
in text format.
|
||||
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: truvi_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: truvi_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: truvi_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
|
||||
truvi_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: truvi_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
|
||||
truvi_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
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue