93 lines
3.2 KiB
SQL
93 lines
3.2 KiB
SQL
{% set ok_status = ("Approved", "Flagged") %}
|
|
{% set rejected_status = "Rejected" %}
|
|
{% set rejected_fee = 0.25 %}
|
|
{% set cancellation_fee = 0.25 %}
|
|
{% set cancellation_threshold = 0.05 %}
|
|
with
|
|
int_edeposit__verifications as (
|
|
select * from {{ ref("int_edeposit__verifications") }}
|
|
),
|
|
stg_core__edeposit_user as (select * from {{ ref("stg_core__edeposit_user") }}),
|
|
int_daily_currency_exchange_rates as (
|
|
select * from {{ ref("int_daily_currency_exchange_rates") }}
|
|
),
|
|
edeposit_records as (
|
|
select
|
|
v.id_verification,
|
|
v.id_user_partner,
|
|
v.id_booking,
|
|
eu.currency,
|
|
cer.rate,
|
|
v.is_cancelled,
|
|
case
|
|
when v.verification_status in {{ ok_status }}
|
|
then v.nightly_fee_local * v.number_nights
|
|
else 0
|
|
end as ok_status_fee_in_txn_currency,
|
|
case
|
|
when v.verification_status in {{ ok_status }}
|
|
then cer.rate * v.nightly_fee_local * v.number_nights
|
|
else 0
|
|
end as ok_status_fee_in_gbp,
|
|
case
|
|
when v.verification_status = '{{ rejected_status }}'
|
|
then {{ rejected_fee }}
|
|
else 0
|
|
end as rejected_fee_in_txn_currency,
|
|
case
|
|
when v.verification_status = '{{ rejected_status }}'
|
|
then cer.rate * {{ rejected_fee }}
|
|
else 0
|
|
end as rejected_fee_in_gbp,
|
|
to_char(v.checkout_at_utc, 'YYYY-MM') as year_month_checkout
|
|
from int_edeposit__verifications v
|
|
inner join stg_core__edeposit_user eu on v.id_user_partner = eu.id_user_partner
|
|
left join
|
|
int_daily_currency_exchange_rates cer
|
|
on cer.from_currency = eu.currency
|
|
and cer.rate_date_utc = v.checkout_date_utc
|
|
and cer.to_currency = 'GBP'
|
|
where version = 'V2'
|
|
),
|
|
monthly_cancellation_threshold as (
|
|
select
|
|
id_user_partner,
|
|
year_month_checkout,
|
|
case
|
|
when
|
|
sum(cast(is_cancelled as integer))::decimal / count(id_booking)
|
|
>= {{ cancellation_threshold }}
|
|
then true
|
|
else false
|
|
end as is_cancellation_threshold_surpassed
|
|
from edeposit_records
|
|
group by id_user_partner, year_month_checkout
|
|
)
|
|
select
|
|
v.id_verification,
|
|
v.id_booking,
|
|
er.currency,
|
|
er.ok_status_fee_in_txn_currency,
|
|
er.ok_status_fee_in_gbp,
|
|
er.rejected_fee_in_txn_currency,
|
|
er.rejected_fee_in_gbp,
|
|
case
|
|
when ct.is_cancellation_threshold_surpassed is true
|
|
then {{ cancellation_fee }}
|
|
else 0
|
|
end as cancelled_fee_in_txn_currency,
|
|
case
|
|
when ct.is_cancellation_threshold_surpassed is true
|
|
then rate * {{ cancellation_fee }}
|
|
else 0
|
|
end as cancelled_fee_in_gbp,
|
|
v.created_date_utc,
|
|
v.checkout_date_utc
|
|
from int_edeposit__verifications v
|
|
inner join edeposit_records er on er.id_verification = v.id_verification
|
|
inner join
|
|
monthly_cancellation_threshold ct
|
|
on (
|
|
er.id_user_partner = ct.id_user_partner
|
|
and er.year_month_checkout = ct.year_month_checkout
|
|
)
|