commit wip

This commit is contained in:
Joaquin Ossa 2025-02-10 11:54:30 +01:00
parent 308a70ece4
commit 369608af05

View file

@ -21,6 +21,10 @@ with
int_core__payaway_per_month_user as (
select * from {{ ref("int_core__payaway_per_month_user") }}
),
int_core__payaway as (select * from {{ ref("int_core__payaway") }}),
int_daily_currency_exchange_rates as (
select * from {{ ref("int_daily_currency_exchange_rates") }}
),
not_taxed_vat_details as (
-- This CTE contains the logic that applies to payments that are not
-- subject to VAT.
@ -175,6 +179,115 @@ with
where
vpt.verification_payment_type = 'Waiver'
and pamu.id_payaway_plan is not null
),
-- CTE to obtain amount due to host and superhog fee.
-- This depends on their payaway plan at the moment of the payment.
-- If they don't have a payaway plan, then superhog is taking the risk.
-- For more details on the calculation, please refer to the documentation.
-- https://www.notion.so/truvi/Guest-Services-Taxes-How-to-calculate-a5ab4c049d61427fafab669dbbffb3a2?pvs=4
payaways as (
select
vtp.id_payment,
pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr
* cer.rate as payaway_minimum_commission_local_curr,
case
when pa.id_payaway_plan is not null then true else false
end as is_host_taking_waiver_risk,
case
when pa.id_payaway_plan is not null
then
p.amount - greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
else 0
end as amount_due_to_host_in_txn_currency,
case
when pa.id_payaway_plan is not null
then
(
p.amount - greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
)
* der.rate
else 0
end as amount_due_to_host_in_gbp,
case
when pa.id_payaway_plan is not null and uu.billing_country_iso_3 = 'GBR'
then
(
greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
)
/ (vat.vat_rate + 1)
when
pa.id_payaway_plan is not null and uu.billing_country_iso_3 <> 'GBR'
then
greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
else p.amount
end as superhog_fee_in_txn_currency,
case
when pa.id_payaway_plan is not null and uu.billing_country_iso_3 = 'GBR'
then
(
greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
)
/ (vat.vat_rate + 1)
* der.rate
when
pa.id_payaway_plan is not null and uu.billing_country_iso_3 <> 'GBR'
then
(
greatest(
p.amount * pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr * cer.rate
)
)
* der.rate
else p.amount
end as superhog_fee_in_gbp
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__verification_request vr
on v.id_verification_request = vr.id_verification_request
left join
int_core__payaway pa
on vr.id_user_host = pa.id_user_host
and p.paid_at_utc
between pa.start_at_utc and coalesce(pa.end_at_utc, '2050-12-31')
left join
int_daily_currency_exchange_rates der
on p.paid_date_utc = der.rate_date_utc
and der.from_currency = p.currency
and der.to_currency = 'GBP'
left join int_core__unified_user uu on vr.id_user_host = uu.id_user
-- We need to exchange the minimum payaway commissions from host currency
-- to currency used by guest in the payment.
left join
int_daily_currency_exchange_rates cer
on p.paid_date_utc = cer.rate_date_utc
and cer.from_currency = uu.account_currency_iso4217
and cer.to_currency = p.currency
left join
stg_seed__guest_services_vat_rates_by_country vat
on uu.billing_country_iso_3 = vat.alpha_3
where upper(vpt.verification_payment_type) = 'WAIVER'
)
select
vtp.id_verification_to_payment,
@ -203,6 +316,9 @@ select
vtp.id_verification,
v.id_verification_request,
vpt.verification_payment_type,
pa.is_host_taking_waiver_risk,
pa.payaway_percentage,
pa.payaway_minimum_commission_local_curr,
p.currency,
p.amount as total_amount_in_txn_currency,
(p.amount * r.rate)::decimal(19, 4) as total_amount_in_gbp,
@ -238,6 +354,10 @@ select
vat.vat_rate,
vat.is_service_subject_to_vat,
vat.is_vat_taxed,
pa.amount_due_to_host_in_txn_currency,
pa.amount_due_to_host_in_gbp,
pa.superhog_fee_in_txn_currency,
pa.superhog_fee_in_gbp,
vat.is_missing_user_country,
vat.are_user_details_deleted,
vat.is_missing_vat_rate_for_country,
@ -271,3 +391,4 @@ left join
from not_taxed_vat_details
) as vat
on vat.id_verification_to_payment = vtp.id_verification_to_payment
left join payaways pa on vtp.id_payment = pa.id_payment