commit wip

This commit is contained in:
Joaquin Ossa 2024-12-23 10:09:46 +01:00
parent 5382a9b32b
commit 1fff7b91a2

View file

@ -0,0 +1,380 @@
{% set rejected_status = "REJECTED" %}
{% set approved_flagged_status = ("APPROVED", "FLAGGED") %}
{% set basic_protection = "BASIC PROTECTION" %}
{% set damage_waiver = "DAMAGE WAIVER" %}
{% set screen_and_protect = "SCREEN & PROTECT" %}
{% set standalone_protection = "STANDALONE PROTECTION" %}
{% set cancel_rejected_fee = 0.25 %}
{% set long_stay_booking_days_threshold = 30 %}
with
int_screen_and_protect__verification_requests as (
select * from {{ ref("int_screen_and_protect__verification_requests") }}
),
stg_core__basic_protection as (
select * from {{ ref("stg_core__basic_protection") }}
),
stg_core__damage_waiver as (select * from {{ ref("stg_core__damage_waiver") }}),
stg_core__screen_and_protect as (
select * from {{ ref("stg_core__screen_and_protect") }}
),
stg_core__standalone_protection as (
select * from {{ ref("stg_core__standalone_protection") }}
),
active_discount_timeframe as (
select distinct
vr.id_user_partner,
date_trunc('month', vr.checkout_date_utc) as verification_month,
case
when
date_trunc('month', vr.checkout_date_utc)
between vr.monthly_general_discount_start_date_utc
and vr.monthly_general_discount_end_date_utc
then 1
else 0
end as is_monthly_general_discount_active,
case
when
date_trunc('month', vr.checkout_date_utc)
between vr.monthly_volume_discount_start_date_utc
and vr.monthly_volume_discount_end_date_utc
then 1
else 0
end as is_monthly_volume_discount_on
from int_screen_and_protect__verification_requests vr
where upper(vr.verification_status) in {{ approved_flagged_status }}
),
approved_verifications as (
select
vr.id_user_partner,
date_trunc('month', vr.checkout_date_utc) as verification_month,
count(*) as monthly_verifications
from int_screen_and_protect__verification_requests vr
where upper(vr.verification_status) in {{ approved_flagged_status }}
group by vr.id_user_partner, date_trunc('month', vr.checkout_date_utc)
),
active_discounts as (
select
av.id_user_partner,
av.verification_month,
av.monthly_verifications,
adt.is_monthly_general_discount_active,
case
when
av.monthly_verifications >= adt.threshold_approved_booking_volume
and adt.is_monthly_volume_discount_on = 1
then 1
else 0
end as is_monthly_volume_discount_active,
adt.is_price_increase_active
from approved_verifications av
left join
active_discount_timeframe adt
on av.id_user_partner = adt.id_user_partner
and av.verification_month = adt.verification_month
)
select
vr.id_verification,
vr.id_booking,
vr.id_user_partner,
vr.id_accommodation,
vr.is_protected,
vr.protection_type,
vr.verification_status,
case
when
vr.number_of_nights > {{ long_stay_booking }}
and upper(vr.verification_status) in {{ approved_flagged_status }}
and vr.is_protected is true
then
bp.long_stay_fee_in_local_currency
* vr.number_of_nights
* (
1
- vr.monthly_volume_discount
/ 100
* ad.is_monthly_volume_discount_active
)
* (
1
- vr.monthly_general_discount
/ 100
* ad.is_monthly_general_discount_active
+ vr.price_increase / 100 * ad.is_price_increase_active
)
when
upper(vr.verification_status) in {{ approved_flagged_status }}
and vr.is_protected is true
then
bp.short_stay_fee_in_local_currency
* vr.number_of_nights
* (
1
- vr.monthly_volume_discount
/ 100
* ad.is_monthly_volume_discount_active
)
* (
1
- vr.monthly_general_discount
/ 100
* ad.is_monthly_general_discount_active
+ vr.price_increase / 100 * ad.is_price_increase_active
)
else 0
end as booking_fee_in_local_currency,
case
when
upper(vr.verification_status) = '{{ rejected_status }}'
or vr.is_cancelled = true
or vr.is_protected is false
then {{ cancel_rejected_fee }}
else 0
end as cancel_or_rejected_fee_in_local_currency,
case
when
upper(vr.verification_status) = '{{ rejected_status }}'
or vr.is_cancelled = true
then creation_date_utc
else checkout_date_utc
end as invoice_date_utc,
vr.id_currency,
vr.checkin_date_utc,
vr.checkout_date_utc,
vr.number_of_nights,
vr.is_cancelled,
vr.cancelled_at_utc,
vr.cancelled_date_utc,
vr.user_email,
vr.company_name,
vr.property_manager_name,
vr.property_manager_email,
vr.listing_name,
vr.listing_address,
vr.listing_town,
vr.listing_country,
vr.listing_postcode,
vr.pets_allowed,
vr.status_updated_at_utc,
vr.status_updated_date_utc,
vr.updated_at_utc,
vr.updated_date_utc,
vr.creation_at_utc,
vr.creation_date_utc,
vr.cosmos_created_date_utc
from int_screen_and_protect__verification_requests vr
inner join
stg_core__basic_protection bp
on vr.id_currency = bp.id_currency
and vr.protection_basic_amount_in_local_currency
= bp.protection_basic_amount_in_local_currency
inner join
active_discounts ad
on vr.id_user_partner = ad.id_user_partner
and date_trunc('month', vr.checkout_date_utc) = ad.verification_month
where upper(vr.protection_type) = '{{ basic_protection }}'
union all
select
vr.id_verification,
vr.id_booking,
vr.id_user_partner,
vr.id_accommodation,
vr.is_protected,
vr.protection_type,
vr.verification_status,
case
when
vr.number_of_nights > {{ long_stay_booking }}
and upper(vr.verification_status) in {{ approved_flagged_status }}
and vr.is_protected is true
then
sp.long_stay_fee_in_local_currency
* vr.number_of_nights
* (
1
- vr.monthly_volume_discount
/ 100
* ad.is_monthly_volume_discount_active
)
* (
1
- vr.monthly_general_discount
/ 100
* ad.is_monthly_general_discount_active
+ vr.price_increase / 100 * ad.is_price_increase_active
)
when
upper(vr.verification_status) in {{ approved_flagged_status }}
and vr.is_protected is true
then
sp.short_stay_fee_in_local_currency
* vr.number_of_nights
* (
1
- vr.monthly_volume_discount
/ 100
* ad.is_monthly_volume_discount_active
)
* (
1
- vr.monthly_general_discount
/ 100
* ad.is_monthly_general_discount_active
+ vr.price_increase / 100 * ad.is_price_increase_active
)
else 0
end as booking_fee_in_local_currency,
case
when
upper(vr.verification_status) = '{{ rejected_status }}'
or vr.is_cancelled = true
or vr.is_protected is false
then {{ cancel_rejected_fee }}
else 0
end as cancel_or_rejected_fee_in_local_currency,
case
when
upper(vr.verification_status) = '{{ rejected_status }}'
or vr.is_cancelled = true
then creation_date_utc
else checkout_date_utc
end as invoice_date_utc,
vr.id_currency,
vr.checkin_date_utc,
vr.checkout_date_utc,
vr.number_of_nights,
vr.is_cancelled,
vr.cancelled_at_utc,
vr.cancelled_date_utc,
vr.user_email,
vr.company_name,
vr.property_manager_name,
vr.property_manager_email,
vr.listing_name,
vr.listing_address,
vr.listing_town,
vr.listing_country,
vr.listing_postcode,
vr.pets_allowed,
vr.status_updated_at_utc,
vr.status_updated_date_utc,
vr.updated_at_utc,
vr.updated_date_utc,
vr.creation_at_utc,
vr.creation_date_utc,
vr.cosmos_created_date_utc
from int_screen_and_protect__verification_requests vr
inner join
stg_core__screen_and_protect sp
on vr.id_currency = sp.id_currency
and vr.protection_basic_amount_in_local_currency
= sp.protection_basic_amount_in_local_currency
and vr.protection_extended_amount_in_local_currency
= sp.protection_extended_amount_in_local_currency
inner join
active_discounts ad
on vr.id_user_partner = ad.id_user_partner
and date_trunc('month', vr.checkout_date_utc) = ad.verification_month
where upper(vr.protection_type) = '{{ screen_and_protect }}'
union all
select
vr.id_verification,
vr.id_booking,
vr.id_user_partner,
vr.id_accommodation,
vr.is_protected,
vr.protection_type,
vr.verification_status,
case
when
vr.number_of_nights > {{ long_stay_booking }}
and upper(vr.verification_status) in {{ approved_flagged_status }}
and vr.is_protected is true
then
sp.long_stay_fee_in_local_currency
* vr.number_of_nights
* (
1
- vr.monthly_volume_discount
/ 100
* ad.is_monthly_volume_discount_active
)
* (
1
- vr.monthly_general_discount
/ 100
* ad.is_monthly_general_discount_active
+ vr.price_increase / 100 * ad.is_price_increase_active
)
when
upper(vr.verification_status) in {{ approved_flagged_status }}
and vr.is_protected is true
then
sp.short_stay_fee_in_local_currency
* vr.number_of_nights
* (
1
- vr.monthly_volume_discount
/ 100
* ad.is_monthly_volume_discount_active
)
* (
1
- vr.monthly_general_discount
/ 100
* ad.is_monthly_general_discount_active
+ vr.price_increase / 100 * ad.is_price_increase_active
)
else 0
end as booking_fee_in_local_currency,
case
when
upper(vr.verification_status) = '{{ rejected_status }}'
or vr.is_cancelled = true
or vr.is_protected is false
then {{ cancel_rejected_fee }}
else 0
end as cancel_or_rejected_fee_in_local_currency,
case
when
upper(vr.verification_status) = '{{ rejected_status }}'
or vr.is_cancelled = true
then creation_date_utc
else checkout_date_utc
end as invoice_date_utc,
vr.id_currency,
vr.checkin_date_utc,
vr.checkout_date_utc,
vr.number_of_nights,
vr.is_cancelled,
vr.cancelled_at_utc,
vr.cancelled_date_utc,
vr.user_email,
vr.company_name,
vr.property_manager_name,
vr.property_manager_email,
vr.listing_name,
vr.listing_address,
vr.listing_town,
vr.listing_country,
vr.listing_postcode,
vr.pets_allowed,
vr.status_updated_at_utc,
vr.status_updated_date_utc,
vr.updated_at_utc,
vr.updated_date_utc,
vr.creation_at_utc,
vr.creation_date_utc,
vr.cosmos_created_date_utc
from int_screen_and_protect__verification_requests vr
inner join
stg_core__standalone_protection sp
on vr.id_currency = sp.id_currency
and vr.protection_starting_amount_in_local_currency
= sp.protection_starting_amount_in_local_currency
and vr.protection_extended_amount_in_local_currency
= sp.protection_extended_amount_in_local_currency
inner join
active_discounts ad
on vr.id_user_partner = ad.id_user_partner
and date_trunc('month', vr.checkout_date_utc) = ad.verification_month
where upper(vr.protection_type) = '{{ standalone_protection }}'