From be6ccbafa772049e8ca0e4b1e0295dd12cd73bd4 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Tue, 4 Feb 2025 11:24:46 +0100 Subject: [PATCH 01/11] Payments model for legacy report --- .../intermediate/core/int_core__payments.sql | 112 ++++++++++++ models/intermediate/core/schema.yml | 165 ++++++++++++++++++ models/reporting/core/core__payments.sql | 33 ++++ models/reporting/core/schema.yml | 165 ++++++++++++++++++ 4 files changed, 475 insertions(+) create mode 100644 models/intermediate/core/int_core__payments.sql create mode 100644 models/reporting/core/core__payments.sql diff --git a/models/intermediate/core/int_core__payments.sql b/models/intermediate/core/int_core__payments.sql new file mode 100644 index 0000000..01c01a2 --- /dev/null +++ b/models/intermediate/core/int_core__payments.sql @@ -0,0 +1,112 @@ +with + int_core__verification_payments as ( + select * from {{ ref("int_core__verification_payments") }} + ), + int_core__user_host as (select * from {{ ref("int_core__user_host") }}), + int_core__payaway as (select * from {{ ref("int_core__payaway") }}), + int_core__bookings as (select * from {{ ref("int_core__bookings") }}), + int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}), + int_daily_currency_exchange_rates as ( + select * from {{ ref("int_daily_currency_exchange_rates") }} + ), + -- 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. + payaways as ( + select + vp.id_payment, + 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 + ) + else 0 + end as amount_due_to_host_in_txn_currency, + 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 + ) + ) + * der.rate + else 0 + end as amount_due_to_host_in_gbp, + case + when pa.id_payaway_plan is not null + then + greatest( + vp.amount_without_taxes_in_txn_currency * pa.payaway_percentage, + pa.payaway_minimum_commission_local_curr + ) + else vp.amount_without_taxes_in_txn_currency + end as superhog_fee_in_txn_currency, + case + when pa.id_payaway_plan is not null + then + greatest( + vp.amount_without_taxes_in_txn_currency * pa.payaway_percentage, + pa.payaway_minimum_commission_local_curr + ) + * der.rate + else vp.amount_without_taxes_in_txn_currency + end as superhog_fee_in_gbp + from int_core__verification_payments vp + left join + int_core__payaway pa + on vp.id_user_host = pa.id_user_host + and vp.payment_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 vp.payment_paid_date_utc = der.rate_date_utc + and der.from_currency = vp.currency + and der.to_currency = 'GBP' + where upper(vp.verification_payment_type) = 'WAIVER' + ) +select + vp.id_payment, + vp.payment_reference, + vp.verification_payment_type, + vp.payment_status, + vp.payment_due_date_utc, + vp.payment_paid_date_utc, + vp.total_amount_in_txn_currency, + vp.total_amount_in_gbp, + vp.amount_without_taxes_in_txn_currency, + vp.amount_without_taxes_in_gbp, + vp.tax_amount_in_txn_currency, + vp.tax_amount_in_gbp, + 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, + vp.currency, + der.rate, + uh.first_name, + uh.last_name, + uh.email, + uh.company_name, + b.guest_first_name, + b.guest_last_name, + b.guest_email, + a.friendly_name, + a.address_line_1, + b.check_in_date_utc, + b.check_out_date_utc, + uh.account_currency_iso4217 as host_currency +from int_core__verification_payments vp +left join int_core__user_host uh on vp.id_user_host = uh.id_user_host +left join payaways pa on vp.id_payment = pa.id_payment +left join int_core__bookings b on vp.id_verification_request = b.id_verification_request +left join int_core__accommodation a on b.id_accommodation = a.id_accommodation +left join + int_daily_currency_exchange_rates der + on vp.payment_paid_date_utc = der.rate_date_utc + and der.from_currency = vp.currency + and der.to_currency = 'GBP' diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index a7e207f..187e513 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -5245,3 +5245,168 @@ models: description: "Number of bookings that have a bundle that considers this service and are flagged." + - name: int_core__payments + description: | + A table holding payment details for guest journeys, including amounts in both + transaction currency and GBP, host and guest information, and payment status. + Currency conversions are done using using data from xexe.com. + + columns: + - name: id_payment + data_type: bigint + description: Unique identifier for the payment. + data_tests: + - not_null + + - name: payment_reference + data_type: character varying + description: Unique reference code associated with the payment. + + - name: verification_payment_type + data_type: character varying + description: Type of payment verification, categorizing the transaction. + data_tests: + - accepted_values: + values: + - "Waiver" + - "Deposit" + - "CheckInCover" + - "Fee" + + - name: payment_status + data_type: character varying + description: Current status of the payment (e.g., pending, paid, refunded). + + - name: payment_due_date_utc + data_type: date + description: The due date for the payment, in UTC. + + - name: payment_paid_date_utc + data_type: date + description: The date when the payment was successfully made, in UTC. + + - name: total_amount_in_txn_currency + data_type: numeric + description: | + The total amount of the payment in local currency. + This includes taxes if applicable. + data_tests: + - not_null + + - name: total_amount_in_gbp + data_type: numeric + description: | + The total amount of the payment in GBP. + This includes taxes if applicable. + data_tests: + - not_null + + - name: amount_without_taxes_in_txn_currency + data_type: numeric + description: | + The net amount of the payment without taxes, in local currency. + data_tests: + - not_null + + - name: amount_without_taxes_in_gbp + data_type: numeric + description: | + The net amount of the payment without taxes, in GBP. + data_tests: + - not_null + + - name: tax_amount_in_txn_currency + data_type: numeric + description: | + The tax portion of the payment, in local currency. + Will be 0 if no taxes apply. + data_tests: + - not_null + + - name: tax_amount_in_gbp + data_type: numeric + description: | + The tax portion of the payment, in GBP. Will be 0 if no + taxes apply. + data_tests: + - not_null + + - name: amount_due_to_host_in_txn_currency + data_type: numeric + description: | + The amount payable to the host, in local currency. + + - name: amount_due_to_host_in_gbp + data_type: numeric + description: | + The amount payable to the host, in GBP. + + - name: superhog_fee_in_txn_currency + data_type: numeric + description: | + The service fee charged by Superhog, in local currency. + + - name: superhog_fee_in_gbp + data_type: numeric + description: | + The service fee charged by Superhog, in GBP. + + - name: currency + data_type: text + description: | + The ISO 4217 currency code (e.g., GBP, USD, EUR) in which the payment + was originally made. + + - name: first_name + data_type: character varying + description: First name of the host receiving the payment. + + - name: last_name + data_type: character varying + description: Last name of the host receiving the payment. + + - name: email + data_type: character varying + description: Email address of the host receiving the payment. + + - name: company_name + data_type: character varying + description: | + The company name of the host. + + - name: guest_first_name + data_type: character varying + description: First name of the guest making the payment. + + - name: guest_last_name + data_type: character varying + description: Last name of the guest making the payment. + + - name: guest_email + data_type: character varying + description: Email address of the guest making the payment. + + - name: friendly_name + data_type: character varying + description: | + A user-friendly name for the booking or transaction, often used for + display purposes. + + - name: address_line_1 + data_type: character varying + description: | + The first line of the property address associated with the payment. + + - name: check_in_date_utc + data_type: date + description: The scheduled check-in date of the guest, in UTC. + + - name: check_out_date_utc + data_type: date + description: The scheduled check-out date of the guest, in UTC. + + - name: host_currency + data_type: character varying + description: | + The currency in which the host receives their payment (may differ from + the transaction currency). diff --git a/models/reporting/core/core__payments.sql b/models/reporting/core/core__payments.sql new file mode 100644 index 0000000..d3b6675 --- /dev/null +++ b/models/reporting/core/core__payments.sql @@ -0,0 +1,33 @@ +with int_core__payments as (select * from {{ ref("int_core__payments") }}) +select + id_payment as id_payment, + payment_reference as payment_reference, + verification_payment_type as verification_payment_type, + payment_status as payment_status, + payment_due_date_utc as payment_due_date_utc, + payment_paid_date_utc as payment_paid_date_utc, + total_amount_in_txn_currency as total_amount_in_txn_currency, + total_amount_in_gbp as total_amount_in_gbp, + amount_without_taxes_in_txn_currency as amount_without_taxes_in_txn_currency, + amount_without_taxes_in_gbp as amount_without_taxes_in_gbp, + tax_amount_in_txn_currency as tax_amount_in_txn_currency, + tax_amount_in_gbp as tax_amount_in_gbp, + amount_due_to_host_in_txn_currency as amount_due_to_host_in_txn_currency, + amount_due_to_host_in_gbp as amount_due_to_host_in_gbp, + 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, + first_name as first_name, + last_name as last_name, + email as email, + company_name as company_name, + guest_first_name as guest_first_name, + guest_last_name as guest_last_name, + guest_email as guest_email, + friendly_name as friendly_name, + address_line_1 as address_line_1, + check_in_date_utc as check_in_date_utc, + check_out_date_utc as check_out_date_utc, + host_currency as host_currency +from int_core__payments diff --git a/models/reporting/core/schema.yml b/models/reporting/core/schema.yml index 40aad3e..f798ae2 100644 --- a/models/reporting/core/schema.yml +++ b/models/reporting/core/schema.yml @@ -1640,3 +1640,168 @@ models: description: "Number of bookings that have a bundle that considers this service and are flagged." + - name: core__payments + description: | + A table holding payment details for guest journeys, including amounts in both + transaction currency and GBP, host and guest information, and payment status. + Currency conversions are done using using data from xexe.com. + + columns: + - name: id_payment + data_type: bigint + description: Unique identifier for the payment. + data_tests: + - not_null + + - name: payment_reference + data_type: character varying + description: Unique reference code associated with the payment. + + - name: verification_payment_type + data_type: character varying + description: Type of payment verification, categorizing the transaction. + data_tests: + - accepted_values: + values: + - "Waiver" + - "Deposit" + - "CheckInCover" + - "Fee" + + - name: payment_status + data_type: character varying + description: Current status of the payment (e.g., pending, paid, refunded). + + - name: payment_due_date_utc + data_type: date + description: The due date for the payment, in UTC. + + - name: payment_paid_date_utc + data_type: date + description: The date when the payment was successfully made, in UTC. + + - name: total_amount_in_txn_currency + data_type: numeric + description: | + The total amount of the payment in local currency. + This includes taxes if applicable. + data_tests: + - not_null + + - name: total_amount_in_gbp + data_type: numeric + description: | + The total amount of the payment in GBP. + This includes taxes if applicable. + data_tests: + - not_null + + - name: amount_without_taxes_in_txn_currency + data_type: numeric + description: | + The net amount of the payment without taxes, in local currency. + data_tests: + - not_null + + - name: amount_without_taxes_in_gbp + data_type: numeric + description: | + The net amount of the payment without taxes, in GBP. + data_tests: + - not_null + + - name: tax_amount_in_txn_currency + data_type: numeric + description: | + The tax portion of the payment, in local currency. + Will be 0 if no taxes apply. + data_tests: + - not_null + + - name: tax_amount_in_gbp + data_type: numeric + description: | + The tax portion of the payment, in GBP. Will be 0 if no + taxes apply. + data_tests: + - not_null + + - name: amount_due_to_host_in_txn_currency + data_type: numeric + description: | + The amount payable to the host, in local currency. + + - name: amount_due_to_host_in_gbp + data_type: numeric + description: | + The amount payable to the host, in GBP. + + - name: superhog_fee_in_txn_currency + data_type: numeric + description: | + The service fee charged by Superhog, in local currency. + + - name: superhog_fee_in_gbp + data_type: numeric + description: | + The service fee charged by Superhog, in GBP. + + - name: currency + data_type: text + description: | + The ISO 4217 currency code (e.g., GBP, USD, EUR) in which the payment + was originally made. + + - name: first_name + data_type: character varying + description: First name of the host receiving the payment. + + - name: last_name + data_type: character varying + description: Last name of the host receiving the payment. + + - name: email + data_type: character varying + description: Email address of the host receiving the payment. + + - name: company_name + data_type: character varying + description: | + The company name of the host. + + - name: guest_first_name + data_type: character varying + description: First name of the guest making the payment. + + - name: guest_last_name + data_type: character varying + description: Last name of the guest making the payment. + + - name: guest_email + data_type: character varying + description: Email address of the guest making the payment. + + - name: friendly_name + data_type: character varying + description: | + A user-friendly name for the booking or transaction, often used for + display purposes. + + - name: address_line_1 + data_type: character varying + description: | + The first line of the property address associated with the payment. + + - name: check_in_date_utc + data_type: date + description: The scheduled check-in date of the guest, in UTC. + + - name: check_out_date_utc + data_type: date + description: The scheduled check-out date of the guest, in UTC. + + - name: host_currency + data_type: character varying + description: | + The currency in which the host receives their payment (may differ from + the transaction currency). From b6bc19269dd60665f98edb202c13a073afe60622 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Tue, 4 Feb 2025 14:14:00 +0100 Subject: [PATCH 02/11] Fixed waiver payment logic --- .../intermediate/core/int_core__payments.sql | 82 +++++++++++++++---- models/intermediate/core/schema.yml | 34 ++++++++ models/reporting/core/core__payments.sql | 8 +- models/reporting/core/schema.yml | 34 ++++++++ 4 files changed, 142 insertions(+), 16 deletions(-) diff --git a/models/intermediate/core/int_core__payments.sql b/models/intermediate/core/int_core__payments.sql index 01c01a2..10e44fa 100644 --- a/models/intermediate/core/int_core__payments.sql +++ b/models/intermediate/core/int_core__payments.sql @@ -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, diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index 187e513..af6c200 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -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. diff --git a/models/reporting/core/core__payments.sql b/models/reporting/core/core__payments.sql index d3b6675..073046b 100644 --- a/models/reporting/core/core__payments.sql +++ b/models/reporting/core/core__payments.sql @@ -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, diff --git a/models/reporting/core/schema.yml b/models/reporting/core/schema.yml index f798ae2..e6656dc 100644 --- a/models/reporting/core/schema.yml +++ b/models/reporting/core/schema.yml @@ -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. From 0d11302a20974edefcbc298b23d53df61670f574 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Wed, 5 Feb 2025 09:40:13 +0100 Subject: [PATCH 03/11] commit wip --- .../intermediate/core/int_core__payments.sql | 26 +++++++++---------- 1 file changed, 12 insertions(+), 14 deletions(-) diff --git a/models/intermediate/core/int_core__payments.sql b/models/intermediate/core/int_core__payments.sql index 10e44fa..043e495 100644 --- a/models/intermediate/core/int_core__payments.sql +++ b/models/intermediate/core/int_core__payments.sql @@ -1,5 +1,3 @@ -{% set uk_tax = 1.2 %} - with int_core__verification_payments as ( select * from {{ ref("int_core__verification_payments") }} @@ -11,6 +9,9 @@ with int_daily_currency_exchange_rates as ( select * from {{ ref("int_daily_currency_exchange_rates") }} ), + stg_seed__guest_services_vat_rates_by_country as ( + select * from {{ ref("stg_seed__guest_services_vat_rates_by_country") }} + ), -- 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. @@ -47,9 +48,7 @@ with else 0 end as amount_due_to_host_in_gbp, case - when - pa.id_payaway_plan is not null - and uh.billing_country_name = 'United Kingdom' + when pa.id_payaway_plan is not null and uh.billing_country_iso_3 = 'GBR' then ( greatest( @@ -57,10 +56,9 @@ with pa.payaway_minimum_commission_local_curr * cer.rate ) ) - / {{ uk_tax }} + / (vat.vat_rate + 1) when - pa.id_payaway_plan is not null - and uh.billing_country_name <> 'United Kingdom' + pa.id_payaway_plan is not null and uh.billing_country_iso_3 <> 'GBR' then greatest( vp.total_amount_in_txn_currency * pa.payaway_percentage, @@ -69,9 +67,7 @@ with else vp.amount_without_taxes_in_txn_currency end as superhog_fee_in_txn_currency, case - when - pa.id_payaway_plan is not null - and uh.billing_country_name = 'United Kingdom' + when pa.id_payaway_plan is not null and uh.billing_country_iso_3 = 'GBR' then ( greatest( @@ -79,11 +75,10 @@ with pa.payaway_minimum_commission_local_curr * cer.rate ) ) - / {{ uk_tax }} + / (vat.vat_rate + 1) * der.rate when - pa.id_payaway_plan is not null - and uh.billing_country_name <> 'United Kingdom' + pa.id_payaway_plan is not null and uh.billing_country_iso_3 <> 'GBR' then ( greatest( @@ -113,6 +108,9 @@ with on vp.payment_paid_date_utc = cer.rate_date_utc and cer.from_currency = uh.account_currency_iso4217 and cer.to_currency = vp.currency + left join + stg_seed__guest_services_vat_rates_by_country vat + on uh.billing_country_iso_3 = vat.alpha_3 where upper(vp.verification_payment_type) = 'WAIVER' ) select From 20f700433d3b23d253a9011eb5cc46bb88237f9c Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Thu, 6 Feb 2025 12:20:33 +0100 Subject: [PATCH 04/11] commit wip --- .../core/int_core__booking_details.sql | 2 +- .../intermediate/core/int_core__payments.sql | 15 +++++++--- models/intermediate/core/schema.yml | 28 +++++++++++++++++-- 3 files changed, 37 insertions(+), 8 deletions(-) diff --git a/models/intermediate/core/int_core__booking_details.sql b/models/intermediate/core/int_core__booking_details.sql index 435b6ef..04800fe 100644 --- a/models/intermediate/core/int_core__booking_details.sql +++ b/models/intermediate/core/int_core__booking_details.sql @@ -73,7 +73,7 @@ select uh.company_name, b.guest_first_name, b.guest_last_name, - b.guest_email, + uu.guest_email, uu.billing_country_name as guest_billing_country, uu.billing_town as guest_billing_town, a.friendly_name, diff --git a/models/intermediate/core/int_core__payments.sql b/models/intermediate/core/int_core__payments.sql index 043e495..4f5be48 100644 --- a/models/intermediate/core/int_core__payments.sql +++ b/models/intermediate/core/int_core__payments.sql @@ -3,6 +3,7 @@ with select * from {{ ref("int_core__verification_payments") }} ), int_core__user_host as (select * from {{ ref("int_core__user_host") }}), + int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}), int_core__payaway as (select * from {{ ref("int_core__payaway") }}), int_core__bookings as (select * from {{ ref("int_core__bookings") }}), int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}), @@ -123,6 +124,9 @@ select vp.payment_status, vp.payment_due_date_utc, vp.payment_paid_date_utc, + vp.refund_payment_reference, + vp.refund_due_date_utc, + vp.payment_refunded_date_utc, vp.total_amount_in_txn_currency, vp.total_amount_in_gbp, vp.amount_without_taxes_in_txn_currency, @@ -137,14 +141,16 @@ select der.rate as exchange_rate_to_gbp, uh.id_user_host, uh.id_deal, - uh.first_name, - uh.last_name, - uh.email, + uh.first_name as host_first_name, + uh.last_name as host_last_name, + uh.email as host_email, uh.company_name, uh.billing_country_name as host_country, b.guest_first_name, b.guest_last_name, - b.guest_email, + uu.guest_email, + uu.billing_country_name as guest_billing_country, + uu.billing_town as guest_billing_town, a.friendly_name, a.address_line_1, b.check_in_date_utc, @@ -152,6 +158,7 @@ select uh.account_currency_iso4217 as host_currency from int_core__verification_payments vp left join int_core__user_host uh on vp.id_user_host = uh.id_user_host +left join int_core__unified_user uu on uu.id_user = b.id_user_guest left join payaways pa on vp.id_payment = pa.id_payment left join int_core__bookings b on vp.id_verification_request = b.id_verification_request left join int_core__accommodation a on b.id_accommodation = a.id_accommodation diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index af6c200..4cef264 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -5297,6 +5297,18 @@ models: data_type: date description: The date when the payment was successfully made, in UTC. + - name: refund_payment_reference + data_type: date + description: The reference code associated with the refund payment. + + - name: refund_due_date_utc + data_type: date + description: The due date for the refund payment, in UTC. + + - name: payment_refunded_date_utc + data_type: date + description: The date when the payment was refunded, in UTC. + - name: total_amount_in_txn_currency data_type: numeric description: | @@ -5386,15 +5398,15 @@ models: 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 + - name: host_first_name data_type: character varying description: First name of the host receiving the payment. - - name: last_name + - name: host_last_name data_type: character varying description: Last name of the host receiving the payment. - - name: email + - name: host_email data_type: character varying description: Email address of the host receiving the payment. @@ -5420,6 +5432,16 @@ models: data_type: character varying description: Email address of the guest making the payment. + - name: guest_billing_country + data_type: text + description: | + The country name of the guest's billing address. + + - name: guest_billing_town + data_type: text + description: | + The town or city name of the guest's billing address. + - name: friendly_name data_type: character varying description: | From 308a70ece4ee16ac0591607134b6b189c49bbaa3 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Fri, 7 Feb 2025 10:21:34 +0100 Subject: [PATCH 05/11] commit wip --- models/intermediate/core/int_core__payments.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/models/intermediate/core/int_core__payments.sql b/models/intermediate/core/int_core__payments.sql index 4f5be48..4fc57ba 100644 --- a/models/intermediate/core/int_core__payments.sql +++ b/models/intermediate/core/int_core__payments.sql @@ -148,7 +148,7 @@ select uh.billing_country_name as host_country, b.guest_first_name, b.guest_last_name, - uu.guest_email, + uu.email as guest_email, uu.billing_country_name as guest_billing_country, uu.billing_town as guest_billing_town, a.friendly_name, @@ -158,9 +158,9 @@ select uh.account_currency_iso4217 as host_currency from int_core__verification_payments vp left join int_core__user_host uh on vp.id_user_host = uh.id_user_host -left join int_core__unified_user uu on uu.id_user = b.id_user_guest left join payaways pa on vp.id_payment = pa.id_payment left join int_core__bookings b on vp.id_verification_request = b.id_verification_request +left join int_core__unified_user uu on uu.id_user = b.id_user_guest left join int_core__accommodation a on b.id_accommodation = a.id_accommodation left join int_daily_currency_exchange_rates der From 369608af054616f01a7e4dbf1e88987fd871fae3 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 10 Feb 2025 11:54:30 +0100 Subject: [PATCH 06/11] commit wip --- .../int_core__verification_payments_v2.sql | 121 ++++++++++++++++++ 1 file changed, 121 insertions(+) diff --git a/models/intermediate/core/int_core__verification_payments_v2.sql b/models/intermediate/core/int_core__verification_payments_v2.sql index 1d92577..4f2661c 100644 --- a/models/intermediate/core/int_core__verification_payments_v2.sql +++ b/models/intermediate/core/int_core__verification_payments_v2.sql @@ -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 From 2f1bf584c4eaa475043a233afaf01de99e405ec8 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 10 Feb 2025 14:11:00 +0100 Subject: [PATCH 07/11] Changed logic to verification_payments --- .../intermediate/core/int_core__payments.sql | 120 +----------------- 1 file changed, 7 insertions(+), 113 deletions(-) diff --git a/models/intermediate/core/int_core__payments.sql b/models/intermediate/core/int_core__payments.sql index 4fc57ba..798e60c 100644 --- a/models/intermediate/core/int_core__payments.sql +++ b/models/intermediate/core/int_core__payments.sql @@ -4,123 +4,18 @@ with ), int_core__user_host as (select * from {{ ref("int_core__user_host") }}), int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}), - int_core__payaway as (select * from {{ ref("int_core__payaway") }}), int_core__bookings as (select * from {{ ref("int_core__bookings") }}), int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}), int_daily_currency_exchange_rates as ( select * from {{ ref("int_daily_currency_exchange_rates") }} - ), - stg_seed__guest_services_vat_rates_by_country as ( - select * from {{ ref("stg_seed__guest_services_vat_rates_by_country") }} - ), - -- 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.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, - case - when pa.id_payaway_plan is not null - then - ( - 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 and uh.billing_country_iso_3 = 'GBR' - then - ( - greatest( - vp.total_amount_in_txn_currency * pa.payaway_percentage, - pa.payaway_minimum_commission_local_curr * cer.rate - ) - ) - / (vat.vat_rate + 1) - when - pa.id_payaway_plan is not null and uh.billing_country_iso_3 <> 'GBR' - then - greatest( - 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 and uh.billing_country_iso_3 = 'GBR' - then - ( - greatest( - vp.total_amount_in_txn_currency * 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 uh.billing_country_iso_3 <> 'GBR' - 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 - end as superhog_fee_in_gbp - from int_core__verification_payments vp - left join - int_core__payaway pa - on vp.id_user_host = pa.id_user_host - and vp.payment_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 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 - left join - stg_seed__guest_services_vat_rates_by_country vat - on uh.billing_country_iso_3 = vat.alpha_3 - 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.is_host_taking_waiver_risk, + vp.payaway_percentage, + vp.payaway_minimum_commission_local_curr, vp.payment_status, vp.payment_due_date_utc, vp.payment_paid_date_utc, @@ -133,10 +28,10 @@ select vp.amount_without_taxes_in_gbp, vp.tax_amount_in_txn_currency, vp.tax_amount_in_gbp, - 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, + vp.amount_due_to_host_in_txn_currency, + vp.amount_due_to_host_in_gbp, + vp.superhog_fee_in_txn_currency, + vp.superhog_fee_in_gbp, vp.currency, der.rate as exchange_rate_to_gbp, uh.id_user_host, @@ -158,7 +53,6 @@ select uh.account_currency_iso4217 as host_currency from int_core__verification_payments vp left join int_core__user_host uh on vp.id_user_host = uh.id_user_host -left join payaways pa on vp.id_payment = pa.id_payment left join int_core__bookings b on vp.id_verification_request = b.id_verification_request left join int_core__unified_user uu on uu.id_user = b.id_user_guest left join int_core__accommodation a on b.id_accommodation = a.id_accommodation From 0a0ef84c4c811dfaed823fd430cde017fdd2365e Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 10 Feb 2025 14:51:03 +0100 Subject: [PATCH 08/11] commit wip --- models/intermediate/core/schema.yml | 37 +++++++++++++++++++++++++++++ 1 file changed, 37 insertions(+) diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index 4cef264..f5dfccb 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -768,6 +768,23 @@ models: versions: - v: 2 columns: + - 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. + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 0.99 + strictly: false + + - name: payaway_minimum_commission_local_curr + data_type: numeric + description: Minimum commission amount in local currency. + - name: total_amount_in_txn_currency data_type: numeric description: | @@ -859,6 +876,26 @@ models: data_tests: - not_null + - name: amount_due_to_host_in_txn_currency + data_type: numeric + description: | + The amount payable to the host, in local currency. + + - name: amount_due_to_host_in_gbp + data_type: numeric + description: | + The amount payable to the host, in GBP. + + - name: superhog_fee_in_txn_currency + data_type: numeric + description: | + The service fee charged by Superhog, in local currency. + + - name: superhog_fee_in_gbp + data_type: numeric + description: | + The service fee charged by Superhog, in GBP. + - name: is_missing_user_country data_type: boolean description: | From f846656989db8921a0c53406152804b94903ffda Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 10 Feb 2025 17:47:40 +0100 Subject: [PATCH 09/11] commit wip --- .../int_core__verification_payments_v2.sql | 130 ++---------------- .../core/int_core__waiver_fees.sql | 124 +++++++++++++++++ 2 files changed, 133 insertions(+), 121 deletions(-) create mode 100644 models/intermediate/core/int_core__waiver_fees.sql diff --git a/models/intermediate/core/int_core__verification_payments_v2.sql b/models/intermediate/core/int_core__verification_payments_v2.sql index 4f2661c..95183fe 100644 --- a/models/intermediate/core/int_core__verification_payments_v2.sql +++ b/models/intermediate/core/int_core__verification_payments_v2.sql @@ -21,10 +21,7 @@ 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") }} - ), + int_core__waiver_fees as (select * from {{ ref("int_core__waiver_fees") }}), not_taxed_vat_details as ( -- This CTE contains the logic that applies to payments that are not -- subject to VAT. @@ -179,115 +176,6 @@ 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, @@ -316,9 +204,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, + wf.is_host_taking_waiver_risk, + wf.payaway_percentage, + wf.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, @@ -354,10 +242,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, + wf.amount_due_to_host_in_txn_currency, + wf.amount_due_to_host_in_gbp, + wf.superhog_fee_in_txn_currency, + wf.superhog_fee_in_gbp, vat.is_missing_user_country, vat.are_user_details_deleted, vat.is_missing_vat_rate_for_country, @@ -391,4 +279,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 +left join int_core__waiver_fees wf on vtp.id_payment = wf.id_payment diff --git a/models/intermediate/core/int_core__waiver_fees.sql b/models/intermediate/core/int_core__waiver_fees.sql new file mode 100644 index 0000000..ca429a7 --- /dev/null +++ b/models/intermediate/core/int_core__waiver_fees.sql @@ -0,0 +1,124 @@ +-- {{ config(materialized="table") }} +with + stg_core__verification_to_payment as ( + select * from {{ ref("stg_core__verification_to_payment") }} + ), + stg_core__verification_payment_type as ( + select * from {{ ref("stg_core__verification_payment_type") }} + ), + stg_core__verification as (select * from {{ ref("stg_core__verification") }}), + stg_core__verification_request as ( + select * from {{ ref("stg_core__verification_request") }} + ), + stg_core__payment as (select * from {{ ref("stg_core__payment") }}), + int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }}), + int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}), + stg_seed__guest_services_vat_rates_by_country as ( + select * from {{ ref("stg_seed__guest_services_vat_rates_by_country") }} + ), + int_core__payaway as (select * from {{ ref("int_core__payaway") }}) +-- 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 +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 + ) + ) + * ser.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) + * ser.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 + ) + ) + * ser.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, {{ var("end_of_time") }}) +left join + int_simple_exchange_rates ser + on p.paid_date_utc = ser.rate_date_utc + and ser.from_currency = p.currency + and ser.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_simple_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' From bc17ee7b4b706d6f4d0b69a8e47da483c681e1ae Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 10 Feb 2025 18:42:15 +0100 Subject: [PATCH 10/11] New waiver fees model --- .../core/int_core__waiver_fees.sql | 11 ++--- models/intermediate/core/schema.yml | 49 +++++++++++++++++++ models/reporting/core/core__payments.sql | 11 +++-- models/reporting/core/schema.yml | 28 +++++++++-- 4 files changed, 87 insertions(+), 12 deletions(-) diff --git a/models/intermediate/core/int_core__waiver_fees.sql b/models/intermediate/core/int_core__waiver_fees.sql index ca429a7..98e8494 100644 --- a/models/intermediate/core/int_core__waiver_fees.sql +++ b/models/intermediate/core/int_core__waiver_fees.sql @@ -1,4 +1,8 @@ --- {{ config(materialized="table") }} +-- Model 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 with stg_core__verification_to_payment as ( select * from {{ ref("stg_core__verification_to_payment") }} @@ -17,11 +21,6 @@ with select * from {{ ref("stg_seed__guest_services_vat_rates_by_country") }} ), int_core__payaway as (select * from {{ ref("int_core__payaway") }}) --- 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 select vtp.id_payment, pa.payaway_percentage, diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index f5dfccb..823f79b 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -5503,3 +5503,52 @@ models: description: | The currency in which the host receives their payment (may differ from the transaction currency). + + - name: int_core__waiver_fees + description: | + "This model contains the fees charged for the Waiver service. It includes + the percentage of the payment that goes to Superhog, the minimum fee around + the amount charged in both local currency and GBP" + columns: + - name: id_payment + data_type: bigint + description: Unique identifier for the payment. + data_tests: + - not_null + + - name: payaway_percentage + data_type: numeric + description: Percentage of the payment that goes to Superhog. + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 0.99 + strictly: false + + - name: payaway_minimum_commission_local_curr + data_type: numeric + description: Minimum commission amount in local currency. + + - name: is_host_taking_waiver_risk + data_type: boolean + description: Boolean indicating whether the host is taking the risk + + - name: amount_due_to_host_in_txn_currency + data_type: numeric + description: | + The amount payable to the host, in local currency. + + - name: amount_due_to_host_in_gbp + data_type: numeric + description: | + The amount payable to the host, in GBP. + + - name: superhog_fee_in_txn_currency + data_type: numeric + description: | + The service fee charged by Superhog, in local currency. + + - name: superhog_fee_in_gbp + data_type: numeric + description: | + The service fee charged by Superhog, in GBP. diff --git a/models/reporting/core/core__payments.sql b/models/reporting/core/core__payments.sql index 073046b..83c26f4 100644 --- a/models/reporting/core/core__payments.sql +++ b/models/reporting/core/core__payments.sql @@ -9,6 +9,9 @@ select payment_status as payment_status, payment_due_date_utc as payment_due_date_utc, payment_paid_date_utc as payment_paid_date_utc, + refund_payment_reference as refund_payment_reference, + refund_due_date_utc as refund_due_date_utc, + payment_refunded_date_utc as payment_refunded_date_utc, total_amount_in_txn_currency as total_amount_in_txn_currency, total_amount_in_gbp as total_amount_in_gbp, amount_without_taxes_in_txn_currency as amount_without_taxes_in_txn_currency, @@ -23,14 +26,16 @@ select 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, + host_first_name as host_first_name, + host_last_name as host_last_name, + host_email as host_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, + guest_billing_country as guest_billing_country, + guest_billing_town as guest_billing_town, friendly_name as friendly_name, address_line_1 as address_line_1, check_in_date_utc as check_in_date_utc, diff --git a/models/reporting/core/schema.yml b/models/reporting/core/schema.yml index e6656dc..187f8d0 100644 --- a/models/reporting/core/schema.yml +++ b/models/reporting/core/schema.yml @@ -1692,6 +1692,18 @@ models: data_type: date description: The date when the payment was successfully made, in UTC. + - name: refund_payment_reference + data_type: date + description: The reference code associated with the refund payment. + + - name: refund_due_date_utc + data_type: date + description: The due date for the refund payment, in UTC. + + - name: payment_refunded_date_utc + data_type: date + description: The date when the payment was refunded, in UTC. + - name: total_amount_in_txn_currency data_type: numeric description: | @@ -1781,15 +1793,15 @@ models: 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 + - name: host_first_name data_type: character varying description: First name of the host receiving the payment. - - name: last_name + - name: host_last_name data_type: character varying description: Last name of the host receiving the payment. - - name: email + - name: host_email data_type: character varying description: Email address of the host receiving the payment. @@ -1815,6 +1827,16 @@ models: data_type: character varying description: Email address of the guest making the payment. + - name: guest_billing_country + data_type: text + description: | + The country name of the guest's billing address. + + - name: guest_billing_town + data_type: text + description: | + The town or city name of the guest's billing address. + - name: friendly_name data_type: character varying description: | From 125325fcf2a86d821008b2c314de88b29da90e5e Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Tue, 11 Feb 2025 10:44:19 +0100 Subject: [PATCH 11/11] Updated model --- .../intermediate/core/int_core__payments.sql | 4 ++ .../int_core__verification_payments_v2.sql | 12 ++++ .../core/int_core__waiver_fees.sql | 24 +------ models/intermediate/core/schema.yml | 64 +++++++++++++++---- models/reporting/core/core__payments.sql | 6 ++ models/reporting/core/schema.yml | 28 ++++++-- 6 files changed, 101 insertions(+), 37 deletions(-) diff --git a/models/intermediate/core/int_core__payments.sql b/models/intermediate/core/int_core__payments.sql index 798e60c..66aad82 100644 --- a/models/intermediate/core/int_core__payments.sql +++ b/models/intermediate/core/int_core__payments.sql @@ -30,8 +30,12 @@ select vp.tax_amount_in_gbp, vp.amount_due_to_host_in_txn_currency, vp.amount_due_to_host_in_gbp, + vp.amount_due_to_host_without_taxes_in_txn_currency, + vp.amount_due_to_host_without_taxes_in_gbp, vp.superhog_fee_in_txn_currency, vp.superhog_fee_in_gbp, + vp.superhog_fee_without_taxes_in_txn_currency, + vp.superhog_fee_without_taxes_in_gbp, vp.currency, der.rate as exchange_rate_to_gbp, uh.id_user_host, diff --git a/models/intermediate/core/int_core__verification_payments_v2.sql b/models/intermediate/core/int_core__verification_payments_v2.sql index 95183fe..be68e70 100644 --- a/models/intermediate/core/int_core__verification_payments_v2.sql +++ b/models/intermediate/core/int_core__verification_payments_v2.sql @@ -243,9 +243,21 @@ select vat.is_service_subject_to_vat, vat.is_vat_taxed, wf.amount_due_to_host_in_txn_currency, + (wf.amount_due_to_host_in_txn_currency / (1 + vat.vat_rate))::decimal( + 19, 4 + ) as amount_due_to_host_without_taxes_in_txn_currency, wf.amount_due_to_host_in_gbp, + (wf.amount_due_to_host_in_gbp / (1 + vat.vat_rate))::decimal( + 19, 4 + ) as amount_due_to_host_without_taxes_in_gbp, wf.superhog_fee_in_txn_currency, + (wf.superhog_fee_in_txn_currency / (1 + vat.vat_rate))::decimal( + 19, 4 + ) as superhog_fee_without_taxes_in_txn_currency, wf.superhog_fee_in_gbp, + (wf.superhog_fee_in_txn_currency / (1 + vat.vat_rate))::decimal( + 19, 4 + ) as superhog_fee_without_taxes_in_gbp, vat.is_missing_user_country, vat.are_user_details_deleted, vat.is_missing_vat_rate_for_country, diff --git a/models/intermediate/core/int_core__waiver_fees.sql b/models/intermediate/core/int_core__waiver_fees.sql index 98e8494..9413e4e 100644 --- a/models/intermediate/core/int_core__waiver_fees.sql +++ b/models/intermediate/core/int_core__waiver_fees.sql @@ -23,6 +23,7 @@ with int_core__payaway as (select * from {{ ref("int_core__payaway") }}) select vtp.id_payment, + uu.billing_country_iso_3, pa.payaway_percentage, pa.payaway_minimum_commission_local_curr * cer.rate as payaway_minimum_commission_local_curr, @@ -51,16 +52,7 @@ select 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' + when pa.id_payaway_plan is not null then greatest( p.amount * pa.payaway_percentage, @@ -69,17 +61,7 @@ select 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) - * ser.rate - when pa.id_payaway_plan is not null and uu.billing_country_iso_3 <> 'GBR' + when pa.id_payaway_plan is not null then ( greatest( diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index 823f79b..3963bb8 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -879,22 +879,42 @@ models: - name: amount_due_to_host_in_txn_currency data_type: numeric description: | - The amount payable to the host, in local currency. + The amount payable to the host with taxes, in local currency. - name: amount_due_to_host_in_gbp data_type: numeric description: | - The amount payable to the host, in GBP. + The amount payable to the host with taxes, in GBP. + + - name: amount_due_to_host_without_taxes_in_txn_currency + data_type: numeric + description: | + The amount payable to the host without taxes, in local currency. + + - name: amount_due_to_host_without_taxes_in_gbp + data_type: numeric + description: | + The amount payable to the host without taxes, in GBP. - name: superhog_fee_in_txn_currency data_type: numeric description: | - The service fee charged by Superhog, in local currency. + The service fee charged by Superhog with taxes, in local currency. - name: superhog_fee_in_gbp data_type: numeric description: | - The service fee charged by Superhog, in GBP. + The service fee charged by Superhog with taxes, in GBP. + + - name: superhog_fee_without_taxes_in_txn_currency + data_type: numeric + description: | + The service fee charged by Superhog without taxes, in local currency. + + - name: superhog_fee_without_taxes_in_gbp + data_type: numeric + description: | + The service fee charged by Superhog without taxes, in GBP. - name: is_missing_user_country data_type: boolean @@ -5395,22 +5415,42 @@ models: - name: amount_due_to_host_in_txn_currency data_type: numeric description: | - The amount payable to the host, in local currency. + The amount payable to the host with taxes, in local currency. - name: amount_due_to_host_in_gbp data_type: numeric description: | - The amount payable to the host, in GBP. + The amount payable to the host with taxes, in GBP. + + - name: amount_due_to_host_without_taxes_in_txn_currency + data_type: numeric + description: | + The amount payable to the host without taxes, in local currency. + + - name: amount_due_to_host_without_taxes_in_gbp + data_type: numeric + description: | + The amount payable to the host without taxes, in GBP. - name: superhog_fee_in_txn_currency data_type: numeric description: | - The service fee charged by Superhog, in local currency. + The service fee charged by Superhog with taxes, in local currency. - name: superhog_fee_in_gbp data_type: numeric description: | - The service fee charged by Superhog, in GBP. + The service fee charged by Superhog with taxes, in GBP. + + - name: superhog_fee_without_taxes_in_txn_currency + data_type: numeric + description: | + The service fee charged by Superhog without taxes, in local currency. + + - name: superhog_fee_without_taxes_in_gbp + data_type: numeric + description: | + The service fee charged by Superhog without taxes, in GBP. - name: currency data_type: text @@ -5536,19 +5576,19 @@ models: - name: amount_due_to_host_in_txn_currency data_type: numeric description: | - The amount payable to the host, in local currency. + The amount payable to the host with taxes, in local currency. - name: amount_due_to_host_in_gbp data_type: numeric description: | - The amount payable to the host, in GBP. + The amount payable to the host with taxes, in GBP. - name: superhog_fee_in_txn_currency data_type: numeric description: | - The service fee charged by Superhog, in local currency. + The service fee charged by Superhog with taxes, in local currency. - name: superhog_fee_in_gbp data_type: numeric description: | - The service fee charged by Superhog, in GBP. + The service fee charged by Superhog with taxes, in GBP. diff --git a/models/reporting/core/core__payments.sql b/models/reporting/core/core__payments.sql index 83c26f4..9715463 100644 --- a/models/reporting/core/core__payments.sql +++ b/models/reporting/core/core__payments.sql @@ -20,8 +20,14 @@ select tax_amount_in_gbp as tax_amount_in_gbp, amount_due_to_host_in_txn_currency as amount_due_to_host_in_txn_currency, amount_due_to_host_in_gbp as amount_due_to_host_in_gbp, + amount_due_to_host_without_taxes_in_txn_currency + as amount_due_to_host_without_taxes_in_txn_currency, + amount_due_to_host_without_taxes_in_gbp as amount_due_to_host_without_taxes_in_gbp, superhog_fee_in_txn_currency as superhog_fee_in_txn_currency, superhog_fee_in_gbp as superhog_fee_in_gbp, + superhog_fee_without_taxes_in_txn_currency + as superhog_fee_without_taxes_in_txn_currency, + superhog_fee_without_taxes_in_gbp as superhog_fee_without_taxes_in_gbp, currency as currency, exchange_rate_to_gbp as exchange_rate_to_gbp, id_user_host as id_user_host, diff --git a/models/reporting/core/schema.yml b/models/reporting/core/schema.yml index 187f8d0..1f30ed7 100644 --- a/models/reporting/core/schema.yml +++ b/models/reporting/core/schema.yml @@ -1753,22 +1753,42 @@ models: - name: amount_due_to_host_in_txn_currency data_type: numeric description: | - The amount payable to the host, in local currency. + The amount payable to the host with taxes, in local currency. - name: amount_due_to_host_in_gbp data_type: numeric description: | - The amount payable to the host, in GBP. + The amount payable to the host with taxes, in GBP. + + - name: amount_due_to_host_without_taxes_in_txn_currency + data_type: numeric + description: | + The amount payable to the host without taxes, in local currency. + + - name: amount_due_to_host_without_taxes_in_gbp + data_type: numeric + description: | + The amount payable to the host without taxes, in GBP. - name: superhog_fee_in_txn_currency data_type: numeric description: | - The service fee charged by Superhog, in local currency. + The service fee charged by Superhog with taxes, in local currency. - name: superhog_fee_in_gbp data_type: numeric description: | - The service fee charged by Superhog, in GBP. + The service fee charged by Superhog with taxes, in GBP. + + - name: superhog_fee_without_taxes_in_txn_currency + data_type: numeric + description: | + The service fee charged by Superhog without taxes, in local currency. + + - name: superhog_fee_without_taxes_in_gbp + data_type: numeric + description: | + The service fee charged by Superhog without taxes, in GBP. - name: currency data_type: text