diff --git a/models/intermediate/core/int_core__screen_and_protect_users.sql b/models/intermediate/core/int_core__screen_and_protect_users.sql index e3e4a2f..0e4a069 100644 --- a/models/intermediate/core/int_core__screen_and_protect_users.sql +++ b/models/intermediate/core/int_core__screen_and_protect_users.sql @@ -4,8 +4,6 @@ with stg_core__apim_user as (select * from {{ ref("stg_core__apim_user") }}), stg_core__apim_user_type as (select * from {{ ref("stg_core__apim_user_type") }}) select - -- note that these ids are not the same as the ones found in Core - -- they are completely unrelated au.id_apim_user, au.id_apim_user_type, au.json_document_user_data ->> 'DealId' as id_deal, diff --git a/models/intermediate/screen_and_protect/int_screen_and_protect__invoice.sql b/models/intermediate/screen_and_protect/int_screen_and_protect__invoice.sql new file mode 100644 index 0000000..63fa2d8 --- /dev/null +++ b/models/intermediate/screen_and_protect/int_screen_and_protect__invoice.sql @@ -0,0 +1,169 @@ +{% 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 = 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, + vr.threshold_approved_booking_volume, + case + when + date_trunc('month', vr.checkout_date_utc) + >= vr.price_increase_start_date_utc + then 1 + else 0 + end as is_price_increase_active + from intermediate.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 intermediate.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 * ad.is_monthly_volume_discount_active + - vr.monthly_general_discount * ad.is_monthly_general_discount_active + + vr.price_increase * 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 * ad.is_monthly_volume_discount_active + - vr.monthly_general_discount * ad.is_monthly_general_discount_active + + vr.price_increase * 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 }}' diff --git a/models/intermediate/screen_and_protect/int_screen_and_protect__verification_requests.sql b/models/intermediate/screen_and_protect/int_screen_and_protect__verification_requests.sql index 3fbc582..a1e3fdb 100644 --- a/models/intermediate/screen_and_protect/int_screen_and_protect__verification_requests.sql +++ b/models/intermediate/screen_and_protect/int_screen_and_protect__verification_requests.sql @@ -4,19 +4,19 @@ with ), int_core__screen_and_protect_users as ( select * from {{ ref("int_core__screen_and_protect_users") }} - ) + ), + stg_core__user as (select * from {{ ref("stg_core__user") }}) select - -- note that these ids are not the same as the ones found in Core - -- they are completely unrelated vr.id_verification, vr.id_booking, vr.id_user_partner, vr.id_accommodation, + u.id_account_currency as id_currency, spu.is_protected, vr.protection_type, - vr.protection_starting_level, - vr.protection_basic_amount, - vr.protection_extended_amount, + vr.protection_starting_level as protection_starting_level_in_local_currency, + vr.protection_basic_amount as protection_basic_amount_in_local_currency, + vr.protection_extended_amount as protection_extended_amount_in_local_currency, vr.pet_protection, vr.verification_status, vr.verification_status_reason, @@ -63,3 +63,4 @@ select from stg_screen_and_protect__verification_requests vr inner join int_core__screen_and_protect_users spu on vr.id_user_partner = spu.id_apim_user +inner join stg_core__user u on spu.id_apim_user = u.id_user diff --git a/models/intermediate/screen_and_protect/schema.yml b/models/intermediate/screen_and_protect/schema.yml index acf0425..4917710 100644 --- a/models/intermediate/screen_and_protect/schema.yml +++ b/models/intermediate/screen_and_protect/schema.yml @@ -55,30 +55,33 @@ models: - "DAMAGE WAIVER" - "PET PROTECTION" - - name: protection_starting_level + - name: protection_starting_level_in_local_currency data_type: numeric description: Field used for protection type "STANDALONE PROTECTION" to indicate the starting level of protection. + In local currency. tests: - dbt_expectations.expect_column_values_to_be_between: min_value: 0 max_value: 100000 strictly: true - - name: protection_basic_amount + - name: protection_basic_amount_in_local_currency data_type: numeric description: Field used for protection type "SCREEN & PROTECT", "BASIC PROTECTION" or "DAMAGE WAIVER" to show the basic amount of protection. + In local currency. tests: - dbt_expectations.expect_column_values_to_be_between: min_value: 0 max_value: 100000 strictly: true - - name: protection_extended_amount + - name: protection_extended_amount_in_local_currency data_type: numeric description: Field used for protection type "SCREEN & PROTECT", or "STANDALONE PROTECTION" to show the basic amount of protection. + In local currency. tests: - dbt_expectations.expect_column_values_to_be_between: min_value: 0