finish columns and schema
This commit is contained in:
parent
63599d7a9b
commit
da3070949a
2 changed files with 96 additions and 6 deletions
|
|
@ -20,7 +20,7 @@ with
|
||||||
vat_details as (
|
vat_details as (
|
||||||
select
|
select
|
||||||
vtp.id_verification_to_payment,
|
vtp.id_verification_to_payment,
|
||||||
vat.vat_rate,
|
coalesce(vat.vat_rate, 0) as vat_rate,
|
||||||
case
|
case
|
||||||
when vpt.verification_payment_type in ('Waiver', 'Fee', 'CheckInCover')
|
when vpt.verification_payment_type in ('Waiver', 'Fee', 'CheckInCover')
|
||||||
then true
|
then true
|
||||||
|
|
@ -35,7 +35,31 @@ with
|
||||||
then false
|
then false
|
||||||
when vat.vat_rate < 1 and vat.vat_rate > 0
|
when vat.vat_rate < 1 and vat.vat_rate > 0
|
||||||
then true
|
then true
|
||||||
end as is_vat_taxed
|
when uu.billing_country_iso_3 is null
|
||||||
|
then false
|
||||||
|
else false
|
||||||
|
end as is_vat_taxed,
|
||||||
|
(uu.billing_country_iso_3 is null) as is_missing_user_country,
|
||||||
|
(
|
||||||
|
uu.billing_country_iso_3 is not null and vat.alpha_3 is null
|
||||||
|
) as is_missing_vat_rate_for_country,
|
||||||
|
(uu.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 uu.billing_country_iso_3 is null
|
||||||
|
then false
|
||||||
|
when uu.is_deleted = true
|
||||||
|
then false
|
||||||
|
when uu.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
|
from stg_core__verification_to_payment vtp
|
||||||
left join
|
left join
|
||||||
stg_core__verification_payment_type vpt
|
stg_core__verification_payment_type vpt
|
||||||
|
|
@ -75,7 +99,7 @@ select
|
||||||
vpt.verification_payment_type,
|
vpt.verification_payment_type,
|
||||||
p.currency,
|
p.currency,
|
||||||
p.amount as total_amount_in_txn_currency,
|
p.amount as total_amount_in_txn_currency,
|
||||||
(p.amount * r.rate)::decimal(19, 4) as total_amount_in_in_gbp,
|
(p.amount * r.rate)::decimal(19, 4) as total_amount_in_gbp,
|
||||||
/*
|
/*
|
||||||
Helping comment for logic below.
|
Helping comment for logic below.
|
||||||
Given that guest payments are tax inclusive, the tax (column
|
Given that guest payments are tax inclusive, the tax (column
|
||||||
|
|
@ -108,6 +132,10 @@ select
|
||||||
vat.vat_rate,
|
vat.vat_rate,
|
||||||
vat.is_service_subject_to_vat,
|
vat.is_service_subject_to_vat,
|
||||||
vat.is_vat_taxed,
|
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,
|
||||||
ps.payment_status,
|
ps.payment_status,
|
||||||
p.notes
|
p.notes
|
||||||
from stg_core__verification_to_payment vtp
|
from stg_core__verification_to_payment vtp
|
||||||
|
|
|
||||||
|
|
@ -988,15 +988,77 @@ models:
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
- name: is_subject_to_vat
|
- name: is_vat_taxed
|
||||||
data_type: boolean
|
data_type: boolean
|
||||||
description: |
|
description: |
|
||||||
Syntactic suger to indicate if there's any VAT on this payment.
|
Syntactic suger to indicate if there's any VAT on this payment.
|
||||||
Will be true if so, false if not for any reason (guest country has
|
Will be true if so, false if not for any reason (guest country has
|
||||||
no VAT, the payment is for a deposit, etc.)
|
no VAT, the payment is for a deposit, etc.)
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- 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.
|
||||||
|
|
||||||
|
# should be uncommented once this ticket gets solved:
|
||||||
|
#tests:
|
||||||
|
# - not_null
|
||||||
|
# - accepted_values:
|
||||||
|
# values:
|
||||||
|
# - false
|
||||||
|
# where: are_user_details_deleted != true or 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.
|
||||||
|
|
||||||
|
# should be uncommented once this ticket gets solved:
|
||||||
|
#tests:
|
||||||
|
# - not_null
|
||||||
|
# - accepted_values:
|
||||||
|
# values:
|
||||||
|
# - false
|
||||||
|
|
||||||
|
- 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.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- false
|
||||||
- include: all
|
- include: all
|
||||||
exclude: [amount_in_txn_currency, amount_in_gbp]
|
exclude: [amount_in_txn_currency, amount_in_gbp]
|
||||||
- name: int_core__country
|
- name: int_core__country
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue