data-dwh-dbt-project/models/intermediate/edeposit/int_edeposit__verification_fees.sql
2024-10-08 14:37:00 +02:00

120 lines
4.3 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 %}
-- mapping of users that have a different id in Cosmos DB so we can join them
{% set mapped_users = {
"6580e7a6da7d1d09344c847d": "011339af-1206-4b4b-bd58-db2588381673",
"3f6e171e-b6a3-4e5d-b178-309cd91fa704": "e2a34440-c382-4352-bb57-60e898752826",
"hello-manhattanbnb-com": "b1e28c21-ddc2-4c2b-9207-62e248ff83aa",
"9471281a-6404-4614-8cf3-66b1c24e6f24": "e2fa2f20-4fcf-4736-b5e5-f8b118ca98fe",
} %}
{% set user_mapping_case %}
case
{% for old_user, new_user in mapped_users.items() %}
when v.id_user_partner = '{{ old_user }}' then '{{ new_user }}'
{% endfor %}
else v.id_user_partner
end
{% endset %}
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,
{{ user_mapping_case }} as id_user_partner,
v.id_booking,
eu.currency,
cer.rate,
v.is_cancelled,
case
when v.verification_status in {{ ok_status }} and is_cancelled = false
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 }} and is_cancelled = false
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 {{ user_mapping_case }} = 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'
),
monthly_cancellation_threshold as (
select
{{ user_mapping_case }} as 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 v
group by id_user_partner, year_month_checkout
)
select
v.id_verification,
v.id_booking,
v.id_user_partner,
v.id_accommodation,
v.listing_town,
v.listing_country,
v.verification_status,
v.channel,
v.company_name,
v.is_cancelled,
er.currency,
v.nightly_fee_local,
v.number_nights,
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 and v.is_cancelled is true
then {{ cancellation_fee }}
else 0
end as cancelled_fee_in_txn_currency,
case
when ct.is_cancellation_threshold_surpassed is true and v.is_cancelled is true
then rate * {{ cancellation_fee }}
else 0
end as cancelled_fee_in_gbp,
v.created_date_utc,
v.cancelled_date_utc,
v.checkin_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
)