apply changes on the right file

This commit is contained in:
Pablo Martin 2024-10-29 14:50:17 +01:00
parent b7aeb8fcd8
commit eb94c321ec

View file

@ -21,20 +21,14 @@ with
int_core__payaway_per_month_user as (
select * from {{ ref("int_core__payaway_per_month_user") }}
),
fee_vat_details as (
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,
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,
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
@ -64,54 +58,12 @@ with
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 = 'Fee'
where vpt.verification_payment_type not in ('Waiver', 'CheckInCover', 'Fee')
-- Current logic is anything that's not in the list above is not taxed.
),
cih_vat_details as (
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
where vpt.verification_payment_type = 'CheckInCover'
),
sh_waiver_vat_details as (
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,
@ -163,9 +115,14 @@ with
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
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
@ -216,71 +173,6 @@ with
where
vpt.verification_payment_type = 'Waiver'
and pamu.id_payaway_plan is not null
),
vat_details as (
select
vtp.id_verification_to_payment,
coalesce(vat.vat_rate, 0) as vat_rate,
case
when vpt.verification_payment_type in ('Fee', 'CheckInCover', 'Waiver')
then true
else false
end as is_service_subject_to_vat,
case
when
vpt.verification_payment_type
not in ('Waiver', 'Fee', 'CheckInCover')
then false
when
vpt.verification_payment_type = 'Waiver'
and pamu.id_payaway_plan is not null -- host takes waiver
then false
when vat.vat_rate = 0
then false
when uu.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,
(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
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 uu on vtp.id_guest_user = uu.id_user
left join
stg_seed__guest_services_vat_rates_by_country vat
on uu.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
)
select
vtp.id_verification_to_payment,
@ -366,4 +258,14 @@ left join
stg_core__verification_request vr
on v.id_verification_request = vr.id_verification_request
left join
vat_details vat on vat.id_verification_to_payment = vtp.id_verification_to_payment
(
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