Merged PR 3371: Update Host takes risk waivers logic
# Description This PR originally started with the intent of modifying the applicable logic for waivers where the host takes the risk (in order to follow the [current state of this specification](https://www.notion.so/knowyourguest-superhog/Guest-Services-Taxes-How-to-calculate-a5ab4c049d61427fafab669dbbffb3a2?pvs=4)). The verification payments model was quite convoluted already: adding this logic was turning it into an unmanageable ball of hair. So I broke the rules and refactored in the same PR. The end result is that: - The model implementation has changed quite a bit. - Behavior for everything but host-takes-risk waivers should remain unchanged. - Behaviour for host-takes-risk waivers should have changed. # Checklist - [X] The edited models and dependants run properly with production data. - [X] The edited models are sufficiently documented. - [X] The edited models contain PK tests, and I've ran and passed them. - [X] I have checked for DRY opportunities with other models and docs. - [X] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #20043
This commit is contained in:
commit
86719b6a10
1 changed files with 131 additions and 37 deletions
|
|
@ -21,52 +21,30 @@ with
|
|||
int_core__payaway_per_month_user as (
|
||||
select * from {{ ref("int_core__payaway_per_month_user") }}
|
||||
),
|
||||
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,
|
||||
case
|
||||
when
|
||||
vpt.verification_payment_type = 'Waiver'
|
||||
and pamu.id_payaway_plan is null -- superhog takes waiver
|
||||
then true
|
||||
when vpt.verification_payment_type in ('Fee', 'CheckInCover')
|
||||
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,
|
||||
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,
|
||||
(
|
||||
uu.billing_country_iso_3 is not null and vat.alpha_3 is null
|
||||
gu.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,
|
||||
(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 uu.billing_country_iso_3 is null
|
||||
when gu.billing_country_iso_3 is null
|
||||
then false
|
||||
when uu.is_deleted = true
|
||||
when gu.is_deleted = true
|
||||
then false
|
||||
when uu.billing_country_iso_3 is not null and vat.alpha_3 is null
|
||||
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
|
||||
|
|
@ -76,10 +54,58 @@ with
|
|||
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 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 uu.billing_country_iso_3 = vat.alpha_3
|
||||
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
|
||||
|
|
@ -89,6 +115,64 @@ 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)
|
||||
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,
|
||||
|
|
@ -174,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_driven_vat_details
|
||||
union all
|
||||
select *
|
||||
from not_taxed_vat_details
|
||||
) as vat
|
||||
on vat.id_verification_to_payment = vtp.id_verification_to_payment
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue