Payments model for legacy report

This commit is contained in:
Joaquin Ossa 2025-02-04 11:24:46 +01:00
parent aa04b1a84f
commit be6ccbafa7
4 changed files with 475 additions and 0 deletions

View file

@ -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'

View file

@ -5245,3 +5245,168 @@ models:
description: description:
"Number of bookings that have a bundle that considers this service and "Number of bookings that have a bundle that considers this service and
are flagged." 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).

View file

@ -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

View file

@ -1640,3 +1640,168 @@ models:
description: description:
"Number of bookings that have a bundle that considers this service and "Number of bookings that have a bundle that considers this service and
are flagged." 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).