add per service CTEs

This commit is contained in:
Pablo Martin 2024-10-28 15:14:27 +01:00
parent 76ec2c7436
commit 2d2d3a3e0e

View file

@ -21,6 +21,202 @@ with
int_core__payaway_per_month_user as (
select * from {{ ref("int_core__payaway_per_month_user") }}
),
fee_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 = 'Fee'
),
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 (
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
),
host_waiver_vat_details as (
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,
(
gu.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 int_core__unified_user hu on vtp.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 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 not null
),
vat_details as (
select
vtp.id_verification_to_payment,