Merged PR 5201: Eliminates Verification Payments v2 + updates exposures
# Description Eliminates Verification Payments v2 + updates exposures # Checklist - [X] Project compiles Related work items: #30024
This commit is contained in:
parent
4cac5aefa5
commit
d5dd6df1c1
5 changed files with 2 additions and 793 deletions
|
|
@ -1,294 +0,0 @@
|
|||
{{ config(materialized="table") }}
|
||||
|
||||
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") }}),
|
||||
stg_core__payment_status as (select * from {{ ref("stg_core__payment_status") }}),
|
||||
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_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.
|
||||
select
|
||||
vtp.id_verification_to_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 stg_core__verification_to_payment vtp
|
||||
left join
|
||||
stg_core__verification_payment_type vpt
|
||||
on vtp.id_verification_payment_type = vpt.id_verification_payment_type
|
||||
left join int_core__unified_user gu on vtp.id_guest_user = gu.id_user
|
||||
left join
|
||||
stg_seed__guest_services_vat_rates_by_country vat
|
||||
on gu.billing_country_iso_3 = vat.alpha_3
|
||||
where
|
||||
vpt.verification_payment_type not in ('Waiver', 'CheckInCover', 'Fee')
|
||||
or vpt.verification_payment_type is null
|
||||
-- Current logic is anything that's not in the list above is not taxed.
|
||||
),
|
||||
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
|
||||
vtp.id_verification_to_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 stg_core__verification_to_payment vtp
|
||||
left join
|
||||
stg_core__verification_payment_type vpt
|
||||
on vtp.id_verification_payment_type = vpt.id_verification_payment_type
|
||||
left join int_core__unified_user gu on vtp.id_guest_user = 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 stg_core__verification v on vtp.id_verification = v.id_verification
|
||||
left join
|
||||
stg_core__verification_request vr
|
||||
on v.id_verification_request = vr.id_verification_request
|
||||
left join
|
||||
int_core__payaway_per_month_user pamu
|
||||
on vr.id_user_host = pamu.id_user_host
|
||||
and vtp.payment_due_at_utc
|
||||
between pamu.active_in_month_start_date_utc and active_in_month_end_date_utc
|
||||
where
|
||||
(vpt.verification_payment_type = 'Waiver' and pamu.id_payaway_plan is null)
|
||||
or vpt.verification_payment_type = 'CheckInCover'
|
||||
or vpt.verification_payment_type = '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
|
||||
vtp.id_verification_to_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 stg_core__verification_to_payment vtp
|
||||
left join
|
||||
stg_core__verification_payment_type vpt
|
||||
on vtp.id_verification_payment_type = vpt.id_verification_payment_type
|
||||
left join stg_core__verification v on vtp.id_verification = v.id_verification
|
||||
left join
|
||||
stg_core__verification_request vr
|
||||
on v.id_verification_request = vr.id_verification_request
|
||||
left join int_core__unified_user hu on vr.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 vr.id_user_host = pamu.id_user_host
|
||||
and vtp.payment_due_at_utc
|
||||
between pamu.active_in_month_start_date_utc and active_in_month_end_date_utc
|
||||
where
|
||||
vpt.verification_payment_type = 'Waiver'
|
||||
and pamu.id_payaway_plan is not null
|
||||
)
|
||||
select
|
||||
vtp.id_verification_to_payment,
|
||||
vtp.id_payment,
|
||||
vtp.is_refundable,
|
||||
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,
|
||||
-- Host User identifier is included to speed up
|
||||
-- KPIs execution, even though the host itself
|
||||
-- has nothing to do with the guest payments.
|
||||
-- ---------------------------------------------
|
||||
-- Pablo here, I promise I'll find a way to improve performance and get rid
|
||||
-- of this uglyness. Oh god, it hurts.
|
||||
vr.id_user_host,
|
||||
vtp.id_guest_user,
|
||||
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,
|
||||
/*
|
||||
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
|
||||
*/
|
||||
(
|
||||
(p.amount - (p.amount / (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,
|
||||
(
|
||||
(p.amount - (p.amount / (1 + vat.vat_rate)))
|
||||
* vat.is_service_subject_to_vat::int
|
||||
* r.rate
|
||||
)::decimal(19, 4) as tax_amount_in_gbp,
|
||||
(p.amount / (1 + vat.vat_rate))::decimal(
|
||||
19, 4
|
||||
) as amount_without_taxes_in_txn_currency,
|
||||
((p.amount / (1 + vat.vat_rate)) * r.rate)::decimal(
|
||||
19, 4
|
||||
) as amount_without_taxes_in_gbp,
|
||||
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_gbp / (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,
|
||||
vat.is_missing_vat_details_without_known_cause,
|
||||
ps.payment_status,
|
||||
p.notes
|
||||
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__payment_status ps on p.id_payment_status = ps.id_payment_status
|
||||
left 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
|
||||
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_verification_to_payment = vtp.id_verification_to_payment
|
||||
left join int_core__waiver_fees wf on vtp.id_payment = wf.id_payment
|
||||
|
|
@ -669,305 +669,6 @@ models:
|
|||
used link since the initial computation was still considering an end
|
||||
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
|
||||
when they happen, what service was being paid, what was the related
|
||||
verification request, etc.
|
||||
|
||||
Currency rates are converted to GBP with our simple exchange rates view.
|
||||
|
||||
Guest taxes get calculated here. 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_verification_to_payment
|
||||
data_type: bigint
|
||||
description: Unique ID for the relation between the payment verification
|
||||
and the payment at hand.
|
||||
data_tests:
|
||||
- unique
|
||||
- not_null
|
||||
- name: id_payment
|
||||
data_type: bigint
|
||||
description: Unique ID for the payment itself.
|
||||
data_tests:
|
||||
- unique
|
||||
- not_null
|
||||
- name: is_refundable
|
||||
data_type: boolean
|
||||
- name: created_at_utc
|
||||
data_type: timestamp without time zone
|
||||
- name: updated_at_utc
|
||||
data_type: timestamp without time zone
|
||||
- name: payment_due_at_utc
|
||||
data_type: timestamp without time zone
|
||||
data_tests:
|
||||
- not_null
|
||||
- name: payment_due_date_utc
|
||||
data_type: date
|
||||
data_tests:
|
||||
- not_null
|
||||
- name: payment_paid_at_utc
|
||||
data_type: timestamp without time zone
|
||||
- name: payment_paid_date_utc
|
||||
data_type: date
|
||||
- name: payment_reference
|
||||
data_type: character varying
|
||||
- name: refund_due_at_utc
|
||||
data_type: timestamp without time zone
|
||||
- name: refund_due_date_utc
|
||||
data_type: date
|
||||
- name: payment_refunded_at_utc
|
||||
data_type: timestamp without time zone
|
||||
- name: payment_refunded_date_utc
|
||||
data_type: date
|
||||
- name: refund_payment_reference
|
||||
data_type: character varying
|
||||
- name: id_user_host
|
||||
data_type: character varying
|
||||
description: |
|
||||
UUID of the Host linked to the Verification Request
|
||||
that has a payment. It's included here to speed up
|
||||
KPIs execution, even though the host itself has nothing
|
||||
to do with the guest payments.
|
||||
- name: id_guest_user
|
||||
data_type: character varying
|
||||
- name: id_verification
|
||||
data_type: bigint
|
||||
- name: id_verification_request
|
||||
data_type: bigint
|
||||
- name: verification_payment_type
|
||||
data_type: character varying
|
||||
- name: currency
|
||||
data_type: character varying
|
||||
data_tests:
|
||||
- not_null
|
||||
- name: amount_in_txn_currency
|
||||
data_type: numeric
|
||||
data_tests:
|
||||
- not_null
|
||||
- name: amount_in_gbp
|
||||
data_type: numeric
|
||||
data_tests:
|
||||
- not_null
|
||||
- name: payment_status
|
||||
data_type: character varying
|
||||
- name: notes
|
||||
data_type: character varying
|
||||
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: |
|
||||
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
|
||||
Superhog.
|
||||
|
||||
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
|
||||
Superhog.
|
||||
|
||||
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 # If we ever have a 100% tax rate... Let's riot working please
|
||||
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: 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: |
|
||||
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
|
||||
- include: all
|
||||
exclude: [amount_in_txn_currency, amount_in_gbp]
|
||||
- name: int_core__country
|
||||
description: |
|
||||
This model contains information regarding countries, such as codes,
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue