v2 model
This commit is contained in:
parent
bde6f12404
commit
4ba6c80d6f
1 changed files with 95 additions and 0 deletions
|
|
@ -0,0 +1,95 @@
|
|||
{{ 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") }}),
|
||||
stg_core__payment_status as (select * from {{ ref("stg_core__payment_status") }}),
|
||||
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") }}
|
||||
)
|
||||
select
|
||||
vtp.id_verification_to_payment,
|
||||
vtp.id_payment,
|
||||
vtp.is_refundable,
|
||||
vtp.created_at_utc,
|
||||
vtp.updated_at_utc,
|
||||
vtp.payment_due_at_utc,
|
||||
vtp.payment_due_date_utc,
|
||||
p.paid_at_utc as payment_paid_at_utc,
|
||||
p.paid_date_utc as payment_paid_date_utc,
|
||||
p.payment_reference,
|
||||
vtp.refund_due_at_utc,
|
||||
vtp.refund_due_date_utc,
|
||||
p.refunded_at_utc as payment_refunded_at_utc,
|
||||
p.refunded_date_utc as payment_refunded_date_utc,
|
||||
p.refund_payment_reference,
|
||||
-- Host User identifier is included to speed up
|
||||
-- KPIs execution, even though the host itself
|
||||
-- has nothing to do with the guest payments.
|
||||
-- ---------------------------------------------
|
||||
-- Pablo here, I promise I'll find a way to improve performance and get rid
|
||||
-- of this uglyness. Oh god, it hurts.
|
||||
vr.id_user_host,
|
||||
vtp.id_guest_user,
|
||||
vtp.id_verification,
|
||||
v.id_verification_request,
|
||||
vpt.verification_payment_type,
|
||||
p.currency,
|
||||
p.amount as total_amount_in_txn_currency,
|
||||
(p.amount * r.rate) as total_amount_in_in_gbp,
|
||||
/*
|
||||
Helping comment for logic below.
|
||||
Given that guest payments are tax inclusive, the tax (column
|
||||
tax_amount_in_txn_currency) is calculated as:
|
||||
paid by guest
|
||||
tax = paid by guest - ( ------------- )
|
||||
1 + VAT Rate
|
||||
|
||||
The amount without tax (column amount_without_taxes_in_txn_currency) gets
|
||||
calculated as:
|
||||
paid by guest
|
||||
amount without tax = ( ------------- )
|
||||
1 + VAT Rate
|
||||
*/
|
||||
(p.amount - (p.amount / (1 + vat.vat_rates))) as tax_amount_in_txn_currency,
|
||||
(p.amount - (p.amount / (1 + vat.vat_rates))) * r.rate as tax_amount_in_gbp,
|
||||
(p.amount / (1 + vat.vat_rates)) as amount_without_taxes_in_txn_currency,
|
||||
(p.amount / (1 + vat.vat_rates)) * r.rate as amount_without_taxes_in_gbp,
|
||||
vat.vat_rate as applicable_vat_tax_rate,
|
||||
case
|
||||
when vat.vat_rate = 0
|
||||
then false
|
||||
when vat.vat_rate < 1 and vat.vat_rate > 0
|
||||
then true
|
||||
end as is_vat_taxed,
|
||||
ps.payment_status,
|
||||
p.notes
|
||||
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__payment_status ps on p.id_payment_status = ps.id_payment_status
|
||||
left join
|
||||
int_simple_exchange_rates r
|
||||
on vtp.payment_due_date_utc = r.rate_date_utc
|
||||
and p.currency = r.from_currency
|
||||
and r.to_currency = 'GBP'
|
||||
left join
|
||||
stg_core__verification_request vr
|
||||
on v.id_verification_request = vr.id_verification_request
|
||||
left join int_core__unified_user uu on vtp.id_guest_user == uu.id_user
|
||||
left join
|
||||
stg_seed__guest_services_vat_rates_by_country vat
|
||||
on uu.billing_country_iso_3 == vat.alpha_3
|
||||
Loading…
Add table
Add a link
Reference in a new issue