Fixed waiver payment logic
This commit is contained in:
parent
be6ccbafa7
commit
b6bc19269d
4 changed files with 142 additions and 16 deletions
|
|
@ -1,3 +1,5 @@
|
|||
{% set uk_tax = 1.2 %}
|
||||
|
||||
with
|
||||
int_core__verification_payments as (
|
||||
select * from {{ ref("int_core__verification_payments") }}
|
||||
|
|
@ -12,15 +14,23 @@ with
|
|||
-- 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
|
||||
vp.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
|
||||
vp.amount_without_taxes_in_txn_currency - greatest(
|
||||
vp.amount_without_taxes_in_txn_currency * pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr
|
||||
vp.total_amount_in_txn_currency - greatest(
|
||||
vp.total_amount_in_txn_currency * pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr * cer.rate
|
||||
)
|
||||
else 0
|
||||
end as amount_due_to_host_in_txn_currency,
|
||||
|
|
@ -28,30 +38,58 @@ with
|
|||
when pa.id_payaway_plan is not null
|
||||
then
|
||||
(
|
||||
vp.amount_without_taxes_in_txn_currency - greatest(
|
||||
vp.amount_without_taxes_in_txn_currency
|
||||
* pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr
|
||||
vp.total_amount_in_txn_currency - greatest(
|
||||
vp.total_amount_in_txn_currency * 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
|
||||
when
|
||||
pa.id_payaway_plan is not null
|
||||
and uh.billing_country_name = 'United Kingdom'
|
||||
then
|
||||
(
|
||||
greatest(
|
||||
vp.total_amount_in_txn_currency * pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr * cer.rate
|
||||
)
|
||||
)
|
||||
/ {{ uk_tax }}
|
||||
when
|
||||
pa.id_payaway_plan is not null
|
||||
and uh.billing_country_name <> 'United Kingdom'
|
||||
then
|
||||
greatest(
|
||||
vp.amount_without_taxes_in_txn_currency * pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr
|
||||
vp.total_amount_in_txn_currency * pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr * cer.rate
|
||||
)
|
||||
else vp.amount_without_taxes_in_txn_currency
|
||||
end as superhog_fee_in_txn_currency,
|
||||
case
|
||||
when pa.id_payaway_plan is not null
|
||||
when
|
||||
pa.id_payaway_plan is not null
|
||||
and uh.billing_country_name = 'United Kingdom'
|
||||
then
|
||||
greatest(
|
||||
vp.amount_without_taxes_in_txn_currency * pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr
|
||||
(
|
||||
greatest(
|
||||
vp.total_amount_in_txn_currency * pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr * cer.rate
|
||||
)
|
||||
)
|
||||
/ {{ uk_tax }}
|
||||
* der.rate
|
||||
when
|
||||
pa.id_payaway_plan is not null
|
||||
and uh.billing_country_name <> 'United Kingdom'
|
||||
then
|
||||
(
|
||||
greatest(
|
||||
vp.total_amount_in_txn_currency * pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr * cer.rate
|
||||
)
|
||||
)
|
||||
* der.rate
|
||||
else vp.amount_without_taxes_in_txn_currency
|
||||
|
|
@ -67,12 +105,23 @@ with
|
|||
on vp.payment_paid_date_utc = der.rate_date_utc
|
||||
and der.from_currency = vp.currency
|
||||
and der.to_currency = 'GBP'
|
||||
left join int_core__user_host uh on vp.id_user_host = uh.id_user_host
|
||||
-- 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 vp.payment_paid_date_utc = cer.rate_date_utc
|
||||
and cer.from_currency = uh.account_currency_iso4217
|
||||
and cer.to_currency = vp.currency
|
||||
where upper(vp.verification_payment_type) = 'WAIVER'
|
||||
)
|
||||
select
|
||||
vp.id_payment,
|
||||
vp.payment_reference,
|
||||
vp.verification_payment_type,
|
||||
pa.is_host_taking_waiver_risk,
|
||||
pa.payaway_percentage,
|
||||
pa.payaway_minimum_commission_local_curr,
|
||||
vp.payment_status,
|
||||
vp.payment_due_date_utc,
|
||||
vp.payment_paid_date_utc,
|
||||
|
|
@ -87,11 +136,14 @@ select
|
|||
pa.superhog_fee_in_txn_currency,
|
||||
pa.superhog_fee_in_gbp,
|
||||
vp.currency,
|
||||
der.rate,
|
||||
der.rate as exchange_rate_to_gbp,
|
||||
uh.id_user_host,
|
||||
uh.id_deal,
|
||||
uh.first_name,
|
||||
uh.last_name,
|
||||
uh.email,
|
||||
uh.company_name,
|
||||
uh.billing_country_name as host_country,
|
||||
b.guest_first_name,
|
||||
b.guest_last_name,
|
||||
b.guest_email,
|
||||
|
|
|
|||
|
|
@ -5273,6 +5273,18 @@ models:
|
|||
- "CheckInCover"
|
||||
- "Fee"
|
||||
|
||||
- name: is_host_taking_waiver_risk
|
||||
data_type: boolean
|
||||
description: Boolean indicating whether the host is taking the risk
|
||||
|
||||
- name: payaway_percentage
|
||||
data_type: numeric
|
||||
description: Percentage of the payment that goes to Superhog.
|
||||
|
||||
- name: payaway_minimum_commission_local_curr
|
||||
data_type: numeric
|
||||
description: Minimum commission amount in local currency.
|
||||
|
||||
- name: payment_status
|
||||
data_type: character varying
|
||||
description: Current status of the payment (e.g., pending, paid, refunded).
|
||||
|
|
@ -5357,6 +5369,23 @@ models:
|
|||
The ISO 4217 currency code (e.g., GBP, USD, EUR) in which the payment
|
||||
was originally made.
|
||||
|
||||
- name: exchange_rate_to_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
The exchange rate used to convert the payment amount from local currency
|
||||
to GBP.
|
||||
|
||||
- name: id_user_host
|
||||
data_type: character varying
|
||||
description: |
|
||||
The unique identifier of the host receiving the payment.
|
||||
|
||||
- name: id_deal
|
||||
data_type: character varying
|
||||
description: |
|
||||
Main identifier of the B2B clients. A Deal can have multiple Hosts.
|
||||
A Host can have only 1 Deal or no Deal at all. This field can be null.
|
||||
|
||||
- name: first_name
|
||||
data_type: character varying
|
||||
description: First name of the host receiving the payment.
|
||||
|
|
@ -5374,6 +5403,11 @@ models:
|
|||
description: |
|
||||
The company name of the host.
|
||||
|
||||
- name: host_country
|
||||
data_type: character varying
|
||||
description: |
|
||||
The country name of the host.
|
||||
|
||||
- name: guest_first_name
|
||||
data_type: character varying
|
||||
description: First name of the guest making the payment.
|
||||
|
|
|
|||
|
|
@ -3,6 +3,9 @@ select
|
|||
id_payment as id_payment,
|
||||
payment_reference as payment_reference,
|
||||
verification_payment_type as verification_payment_type,
|
||||
is_host_taking_waiver_risk as is_host_taking_waiver_risk,
|
||||
payaway_percentage as payaway_percentage,
|
||||
payaway_minimum_commission_local_curr as payaway_minimum_commission_local_curr,
|
||||
payment_status as payment_status,
|
||||
payment_due_date_utc as payment_due_date_utc,
|
||||
payment_paid_date_utc as payment_paid_date_utc,
|
||||
|
|
@ -17,11 +20,14 @@ select
|
|||
superhog_fee_in_txn_currency as superhog_fee_in_txn_currency,
|
||||
superhog_fee_in_gbp as superhog_fee_in_gbp,
|
||||
currency as currency,
|
||||
rate as rate,
|
||||
exchange_rate_to_gbp as exchange_rate_to_gbp,
|
||||
id_user_host as id_user_host,
|
||||
id_deal as id_deal,
|
||||
first_name as first_name,
|
||||
last_name as last_name,
|
||||
email as email,
|
||||
company_name as company_name,
|
||||
host_country as host_country,
|
||||
guest_first_name as guest_first_name,
|
||||
guest_last_name as guest_last_name,
|
||||
guest_email as guest_email,
|
||||
|
|
|
|||
|
|
@ -1668,6 +1668,18 @@ models:
|
|||
- "CheckInCover"
|
||||
- "Fee"
|
||||
|
||||
- name: is_host_taking_waiver_risk
|
||||
data_type: boolean
|
||||
description: Boolean indicating whether the host is taking the risk
|
||||
|
||||
- name: payaway_percentage
|
||||
data_type: numeric
|
||||
description: Percentage of the payment that goes to Superhog.
|
||||
|
||||
- name: payaway_minimum_commission_local_curr
|
||||
data_type: numeric
|
||||
description: Minimum commission amount in local currency.
|
||||
|
||||
- name: payment_status
|
||||
data_type: character varying
|
||||
description: Current status of the payment (e.g., pending, paid, refunded).
|
||||
|
|
@ -1752,6 +1764,23 @@ models:
|
|||
The ISO 4217 currency code (e.g., GBP, USD, EUR) in which the payment
|
||||
was originally made.
|
||||
|
||||
- name: exchange_rate_to_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
The exchange rate used to convert the payment amount from local currency
|
||||
to GBP.
|
||||
|
||||
- name: id_user_host
|
||||
data_type: character varying
|
||||
description: |
|
||||
The unique identifier of the host receiving the payment.
|
||||
|
||||
- name: id_deal
|
||||
data_type: character varying
|
||||
description: |
|
||||
Main identifier of the B2B clients. A Deal can have multiple Hosts.
|
||||
A Host can have only 1 Deal or no Deal at all. This field can be null.
|
||||
|
||||
- name: first_name
|
||||
data_type: character varying
|
||||
description: First name of the host receiving the payment.
|
||||
|
|
@ -1769,6 +1798,11 @@ models:
|
|||
description: |
|
||||
The company name of the host.
|
||||
|
||||
- name: host_country
|
||||
data_type: character varying
|
||||
description: |
|
||||
The country name of the host.
|
||||
|
||||
- name: guest_first_name
|
||||
data_type: character varying
|
||||
description: First name of the guest making the payment.
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue