This commit is contained in:
Pablo Martin 2024-10-29 14:50:52 +01:00
parent eb94c321ec
commit 233d0f76ca
2 changed files with 2 additions and 273 deletions

View file

@ -120,7 +120,7 @@ with
or vpt.verification_payment_type = 'CheckInCover'
or vpt.verification_payment_type = 'Fee'
),
host_waiver_vat_details as (
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
@ -263,7 +263,7 @@ left join
from guest_driven_vat_details
union all
select *
from host_waiver_vat_details
from host_driven_vat_details
union all
select *
from not_taxed_vat_details

View file

@ -1,271 +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") }}
),
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')
-- 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_waiver_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,
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,
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_waiver_vat_details
union all
select *
from not_taxed_vat_details
) as vat
on vat.id_verification_to_payment = vtp.id_verification_to_payment