From 1fff7b91a29458e7e80a10978fbe1e256c26bedd Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 23 Dec 2024 10:09:46 +0100 Subject: [PATCH 1/5] commit wip --- .../int_screen_and_protect__invoices.sql | 380 ++++++++++++++++++ 1 file changed, 380 insertions(+) create mode 100644 models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql diff --git a/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql b/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql new file mode 100644 index 0000000..96e7dba --- /dev/null +++ b/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql @@ -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 }}' From 9a4c7a312dc05c1ee2127c22cadc9f4a7877e50f Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 23 Dec 2024 15:25:38 +0100 Subject: [PATCH 2/5] Invoice model completed --- .../int_core__screen_and_protect_users.sql | 9 +- models/intermediate/core/schema.yml | 8 +- .../int_screen_and_protect__invoices.sql | 465 +++++++----------- ...een_and_protect__verification_requests.sql | 8 +- .../screen_and_protect/schema.yml | 8 +- 5 files changed, 201 insertions(+), 297 deletions(-) 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 32671dc..d279445 100644 --- a/models/intermediate/core/int_core__screen_and_protect_users.sql +++ b/models/intermediate/core/int_core__screen_and_protect_users.sql @@ -18,19 +18,20 @@ select then true else false end as is_protected, - (au.json_document_user_data ->> 'PriceIncrease')::decimal as price_increase, + (au.json_document_user_data ->> 'PriceIncrease')::decimal + as price_increase_percentage, (au.json_document_user_data ->> 'PriceIncreaseStartDate')::date as price_increase_start_date_utc, (au.json_document_user_data ->> 'MonthlyVolumeDiscount')::decimal - as monthly_volume_discount, + as monthly_volume_discount_percentage, (au.json_document_user_data ->> 'ThresholdApprovedBookingVolume')::integer - as threshold_approved_booking_volume, + as threshold_approved_or_flagged_booking_volume, (au.json_document_user_data ->> 'MonthlyVolumeDiscountStartDate')::date as monthly_volume_discount_start_date_utc, (au.json_document_user_data ->> 'MonthlyVolumeDiscountEndDate')::date as monthly_volume_discount_end_date_utc, (au.json_document_user_data ->> 'MonthlyGeneralDiscount')::decimal - as monthly_general_discount, + as monthly_general_discount_percentage, (au.json_document_user_data ->> 'MonthlyGeneralDiscountStartDate')::date as monthly_general_discount_start_date_utc, (au.json_document_user_data ->> 'MonthlyGeneralDiscountEndDate')::date diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index ee050a2..9f91df2 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -4742,7 +4742,7 @@ models: data_tests: - not_null - - name: price_increase + - name: price_increase_percentage data_type: numeric description: The percentage or value of the price increase applied to the user's account. @@ -4758,7 +4758,7 @@ models: data_tests: - is_first_day_of_month - - name: monthly_volume_discount + - name: monthly_volume_discount_percentage data_type: numeric description: The discount percentage or value offered based on the volume of bookings achieved within a month. @@ -4769,7 +4769,7 @@ models: max_value: 100 strictly: true - - name: threshold_approved_booking_volume + - name: threshold_approved_or_flagged_booking_volume data_type: numeric description: The minimum number of bookings required to qualify for the monthly volume discount. @@ -4792,7 +4792,7 @@ models: data_tests: - is_last_day_of_month - - name: monthly_general_discount + - name: monthly_general_discount_percentage data_type: numeric description: The general discount percentage or value applied to all bookings within the applicable period. diff --git a/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql b/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql index 96e7dba..e62c345 100644 --- a/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql +++ b/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql @@ -4,7 +4,7 @@ {% set damage_waiver = "DAMAGE WAIVER" %} {% set screen_and_protect = "SCREEN & PROTECT" %} {% set standalone_protection = "STANDALONE PROTECTION" %} -{% set cancel_rejected_fee = 0.25 %} +{% set cancelled_rejected_fee = 0.25 %} {% set long_stay_booking_days_threshold = 30 %} with int_screen_and_protect__verification_requests as ( @@ -39,17 +39,20 @@ with and vr.monthly_volume_discount_end_date_utc then 1 else 0 - end as is_monthly_volume_discount_on + end as is_monthly_volume_discount_on, + vr.threshold_approved_or_flagged_booking_volume from int_screen_and_protect__verification_requests vr where upper(vr.verification_status) in {{ approved_flagged_status }} ), - approved_verifications as ( + approved_or_flagged_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 }} + where + upper(vr.verification_status) in {{ approved_flagged_status }} + and vr.is_protected is true group by vr.id_user_partner, date_trunc('month', vr.checkout_date_utc) ), active_discounts as ( @@ -60,17 +63,174 @@ with adt.is_monthly_general_discount_active, case when - av.monthly_verifications >= adt.threshold_approved_booking_volume + av.monthly_verifications + >= adt.threshold_approved_or_flagged_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 + end as is_monthly_volume_discount_active + from approved_or_flagged_verifications av left join active_discount_timeframe adt on av.id_user_partner = adt.id_user_partner and av.verification_month = adt.verification_month + ), + -- All rejected bookings, including those with flagged status but the user's + -- protection is not active + rejected_bookings as ( + select + vr.id_verification, + {{ cancelled_rejected_fee }} as booking_fee_in_local_currency, + vr.creation_date_utc as invoice_date_utc + from int_screen_and_protect__verification_requests vr + where + upper(vr.verification_status) = '{{ rejected_status }}' + or vr.is_protected is false + ), + -- All cancelled bookings, excluding those with damage waiver protection or that + -- have been charged the rejected fee + cancelled_bookings as ( + select + vr.id_verification, + {{ cancelled_rejected_fee }} as booking_fee_in_local_currency, + vr.cancelled_date_utc as invoice_date_utc + from int_screen_and_protect__verification_requests vr + where + upper(vr.protection_type) <> '{{ damage_waiver }}' + and vr.is_cancelled = true + and upper(vr.verification_status) <> '{{ rejected_status }}' + and vr.is_protected is true + ), + -- Damage Waiver bookings that have been approved or flagged, including cancelled + -- ones. + damage_waiver_bookings as ( + select + vr.id_verification, + dw.booking_fee_in_local_currency, + vr.creation_date_utc as invoice_date_utc + from int_screen_and_protect__verification_requests vr + inner join + stg_core__damage_waiver dw + on vr.id_currency = dw.id_currency + and vr.protection_basic_amount_in_local_currency + = dw.protection_basic_amount_in_local_currency + where + upper(vr.protection_type) = '{{ damage_waiver }}' + and upper(vr.verification_status) <> '{{ rejected_status }}' + ), + bookings_with_booking_fee as ( + select * + from rejected_bookings + union all + select * + from cancelled_bookings + union all + select * + from damage_waiver_bookings + ), + -- Basic Protection bookings that have been approved or flagged and are not + -- cancelled. + approved_or_flagged_basic_protection_bookings as ( + select + vr.id_verification, + case + when vr.number_of_nights > {{ long_stay_booking_days_threshold }} + then bp.long_stay_fee_in_local_currency + else bp.short_stay_fee_in_local_currency + end as nightly_fee_in_local_currency, + vr.monthly_volume_discount_percentage * ad.is_monthly_volume_discount_active + + vr.monthly_general_discount_percentage + * ad.is_monthly_general_discount_active as discount_percentage, + vr.checkout_date_utc as invoice_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 }}' + and upper(vr.verification_status) in {{ approved_flagged_status }} + and vr.is_cancelled is false + and vr.is_protected is true + ), + -- Screen & Protect bookings that have been approved or flagged and are not + -- cancelled. + approved_or_flagged_screen_and_protect_bookings as ( + select + vr.id_verification, + case + when vr.number_of_nights > {{ long_stay_booking_days_threshold }} + then sp.long_stay_fee_in_local_currency + else sp.short_stay_fee_in_local_currency + end as nightly_fee_in_local_currency, + vr.monthly_volume_discount_percentage * ad.is_monthly_volume_discount_active + + vr.monthly_general_discount_percentage + * ad.is_monthly_general_discount_active as discount_percentage, + vr.checkout_date_utc as invoice_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 }}' + and upper(vr.verification_status) in {{ approved_flagged_status }} + and vr.is_cancelled is false + and vr.is_protected is true + ), + -- Standalone Protection bookings that have been approved or flagged and are not + -- cancelled. + approved_or_flagged_standalone_protection_bookings as ( + select + vr.id_verification, + case + when vr.number_of_nights > {{ long_stay_booking_days_threshold }} + then sp.long_stay_fee_in_local_currency + else sp.short_stay_fee_in_local_currency + end as nightly_fee_in_local_currency, + vr.monthly_volume_discount_percentage * ad.is_monthly_volume_discount_active + + vr.monthly_general_discount_percentage + * ad.is_monthly_general_discount_active as discount_percentage, + vr.checkout_date_utc as invoice_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 }}' + and upper(vr.verification_status) in {{ approved_flagged_status }} + and vr.is_cancelled is false + and vr.is_protected is true + ), + bookings_with_nightly_fee as ( + select * + from approved_or_flagged_basic_protection_bookings + union all + select * + from approved_or_flagged_screen_and_protect_bookings + union all + select * + from approved_or_flagged_standalone_protection_bookings ) select vr.id_verification, @@ -80,63 +240,6 @@ select 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, @@ -144,6 +247,20 @@ select vr.is_cancelled, vr.cancelled_at_utc, vr.cancelled_date_utc, + bbf.booking_fee_in_local_currency, + bnf.nightly_fee_in_local_currency, + bnf.nightly_fee_in_local_currency + * vr.number_of_nights as total_fee_in_local_currency, + bnf.discount_percentage, + bnf.nightly_fee_in_local_currency + * vr.number_of_nights + * bnf.discount_percentage + / 100 as discount_amount_in_local_currency, + bnf.nightly_fee_in_local_currency + * vr.number_of_nights + * (1 - bnf.discount_percentage) + / 100 as fee_after_discount_in_local_currency, + coalesce(bbf.invoice_date_utc, bnf.invoice_date_utc) as invoice_date_utc, vr.user_email, vr.company_name, vr.property_manager_name, @@ -162,219 +279,5 @@ select 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 }}' +left join bookings_with_booking_fee bbf on vr.id_verification = bbf.id_verification +left join bookings_with_nightly_fee bnf on vr.id_verification = bnf.id_verification 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 0a87d8a..9fcdbd6 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 @@ -19,13 +19,13 @@ select vr.pet_protection, vr.verification_status, vr.verification_status_reason, - spu.price_increase, + spu.price_increase_percentage, spu.price_increase_start_date_utc, - spu.monthly_volume_discount, - spu.threshold_approved_booking_volume, + spu.monthly_volume_discount_percentage, + spu.threshold_approved_or_flagged_booking_volume, spu.monthly_volume_discount_start_date_utc, spu.monthly_volume_discount_end_date_utc, - spu.monthly_general_discount, + spu.monthly_general_discount_percentage, spu.monthly_general_discount_start_date_utc, spu.monthly_general_discount_end_date_utc, vr.email_flag, diff --git a/models/intermediate/screen_and_protect/schema.yml b/models/intermediate/screen_and_protect/schema.yml index b7a3a04..a608224 100644 --- a/models/intermediate/screen_and_protect/schema.yml +++ b/models/intermediate/screen_and_protect/schema.yml @@ -113,7 +113,7 @@ models: - "FLAGGED" - "REJECTED" - - name: price_increase + - name: price_increase_percentage data_type: numeric description: The percentage or value of the price increase applied to the user's account. @@ -129,7 +129,7 @@ models: data_tests: - is_first_day_of_month - - name: monthly_volume_discount + - name: monthly_volume_discount_percentage data_type: numeric description: The discount percentage or value offered based on the volume of bookings achieved within a month. @@ -140,7 +140,7 @@ models: max_value: 100 strictly: true - - name: threshold_approved_booking_volume + - name: threshold_approved_or_flagged_booking_volume data_type: numeric description: The minimum number of bookings required to qualify for the monthly volume discount. @@ -163,7 +163,7 @@ models: data_tests: - is_last_day_of_month - - name: monthly_general_discount + - name: monthly_general_discount_percentage data_type: numeric description: The general discount percentage or value applied to all bookings within the applicable period. From 60ebb13f1d9f071929c544767208c8053026095f Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 23 Dec 2024 16:20:12 +0100 Subject: [PATCH 3/5] Completed schema --- .../int_screen_and_protect__invoices.sql | 40 ++- .../screen_and_protect/schema.yml | 295 +++++++++++++++++- 2 files changed, 319 insertions(+), 16 deletions(-) diff --git a/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql b/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql index e62c345..9799706 100644 --- a/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql +++ b/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql @@ -85,7 +85,10 @@ with from int_screen_and_protect__verification_requests vr where upper(vr.verification_status) = '{{ rejected_status }}' - or vr.is_protected is false + or ( + vr.is_protected is false + and upper(vr.protection_type) <> '{{ damage_waiver }}' + ) ), -- All cancelled bookings, excluding those with damage waiver protection or that -- have been charged the rejected fee @@ -138,9 +141,13 @@ with then bp.long_stay_fee_in_local_currency else bp.short_stay_fee_in_local_currency end as nightly_fee_in_local_currency, - vr.monthly_volume_discount_percentage * ad.is_monthly_volume_discount_active - + vr.monthly_general_discount_percentage - * ad.is_monthly_general_discount_active as discount_percentage, + coalesce( + vr.monthly_volume_discount_percentage + * ad.is_monthly_volume_discount_active + + vr.monthly_general_discount_percentage + * ad.is_monthly_general_discount_active, + 0 + ) as discount_percentage, vr.checkout_date_utc as invoice_date_utc from int_screen_and_protect__verification_requests vr inner join @@ -168,9 +175,13 @@ with then sp.long_stay_fee_in_local_currency else sp.short_stay_fee_in_local_currency end as nightly_fee_in_local_currency, - vr.monthly_volume_discount_percentage * ad.is_monthly_volume_discount_active - + vr.monthly_general_discount_percentage - * ad.is_monthly_general_discount_active as discount_percentage, + coalesce( + vr.monthly_volume_discount_percentage + * ad.is_monthly_volume_discount_active + + vr.monthly_general_discount_percentage + * ad.is_monthly_general_discount_active, + 0 + ) as discount_percentage, vr.checkout_date_utc as invoice_date_utc from int_screen_and_protect__verification_requests vr inner join @@ -200,9 +211,13 @@ with then sp.long_stay_fee_in_local_currency else sp.short_stay_fee_in_local_currency end as nightly_fee_in_local_currency, - vr.monthly_volume_discount_percentage * ad.is_monthly_volume_discount_active - + vr.monthly_general_discount_percentage - * ad.is_monthly_general_discount_active as discount_percentage, + coalesce( + vr.monthly_volume_discount_percentage + * ad.is_monthly_volume_discount_active + + vr.monthly_general_discount_percentage + * ad.is_monthly_general_discount_active, + 0 + ) as discount_percentage, vr.checkout_date_utc as invoice_date_utc from int_screen_and_protect__verification_requests vr inner join @@ -239,6 +254,9 @@ select vr.id_accommodation, vr.is_protected, vr.protection_type, + vr.protection_basic_amount_in_local_currency, + vr.protection_starting_amount_in_local_currency, + vr.protection_extended_amount_in_local_currency, vr.verification_status, vr.id_currency, vr.checkin_date_utc, @@ -258,7 +276,7 @@ select / 100 as discount_amount_in_local_currency, bnf.nightly_fee_in_local_currency * vr.number_of_nights - * (1 - bnf.discount_percentage) + * (100 - bnf.discount_percentage) / 100 as fee_after_discount_in_local_currency, coalesce(bbf.invoice_date_utc, bnf.invoice_date_utc) as invoice_date_utc, vr.user_email, diff --git a/models/intermediate/screen_and_protect/schema.yml b/models/intermediate/screen_and_protect/schema.yml index a608224..a5fb847 100644 --- a/models/intermediate/screen_and_protect/schema.yml +++ b/models/intermediate/screen_and_protect/schema.yml @@ -9,8 +9,8 @@ models: data_tests: - at_least_one_null: columns: - - monthly_volume_discount - - monthly_general_discount + - monthly_volume_discount_percentage + - monthly_general_discount_percentage columns: - name: id_verification data_type: text @@ -215,15 +215,22 @@ models: - name: checkin_date_utc data_type: date - description: Check-in date for the booking. + description: "Check-in date for the booking." + tests: + - not_null - name: checkout_date_utc data_type: date - description: Check-out date for the booking. + description: "Check-out date for the booking." + tests: + - not_null - name: number_of_nights data_type: integer - description: Number of nights for the booking. + description: Number of nights for the reservation. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 1 - name: is_cancelled data_type: boolean @@ -338,3 +345,281 @@ models: Date of when the verification request was created in Cosmos DB. data_tests: - not_null + + - name: int_screen_and_protect__invoices + description: | + This table contains records of invoices related to verification requests + from the Screen and Protect API. + It tracks financial details such as fees, discounts, and booking-related + metadata. + columns: + - name: id_verification + data_type: text + description: "Unique identifier for the verification request." + tests: + - not_null + - unique + + - name: id_booking + data_type: text + description: "Unique identifier for the booking associated with the verification." + tests: + - not_null + + - name: id_user_partner + data_type: text + description: "Identifier for the partner user initiating the verification." + tests: + - not_null + + - name: id_accommodation + data_type: text + description: "Identifier for the accommodation related to the booking." + + - name: is_protected + data_type: boolean + description: "Indicates if the booking is protected or not." + + - name: protection_type + data_type: text + description: "Specific protection type for the request." + tests: + - not_null + - accepted_values: + values: + - "SCREEN & PROTECT" + - "BASIC PROTECTION" + - "STANDALONE PROTECTION" + - "DAMAGE WAIVER" + - "PET PROTECTION" + + - name: protection_starting_amount_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_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_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 + max_value: 50000000 + strictly: true + + - name: pet_protection + data_type: boolean + description: Indicates if pet protection was included. + + - name: verification_status + data_type: text + description: Outcome of the verification process. + tests: + - not_null + - accepted_values: + values: + - "APPROVED" + - "FLAGGED" + - "REJECTED" + + - name: id_currency + data_type: bigint + description: "Id of the currency, works as a foreign key to the + currency table" + tests: + - not_null + - relationships: + to: ref('stg_core__currency') + field: id_currency + + - name: checkin_date_utc + data_type: date + description: "Check-in date for the booking." + tests: + - not_null + + - name: checkout_date_utc + data_type: date + description: "Check-out date for the booking." + tests: + - not_null + + - name: number_of_nights + data_type: integer + description: Number of nights for the reservation. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 1 + + - name: is_cancelled + data_type: boolean + description: "Indicates if the booking was canceled." + + - name: cancelled_at_utc + data_type: timestamp without time zone + description: "Timestamp when the booking was canceled." + + - name: cancelled_date_utc + data_type: date + description: "Date when the booking was canceled." + + - name: booking_fee_in_local_currency + data_type: numeric + description: "Fee in local currency associated with the booking." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 10000 + strictly: true + + - name: nightly_fee_in_local_currency + data_type: numeric + description: "Nightly fee in local currency for the booking." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 10000 + strictly: true + + - name: total_fee_in_local_currency + data_type: numeric + description: "Total fee in local currency, inclusive of all charges." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 10000000 + strictly: true + + - name: discount_percentage + data_type: numeric + description: "Percentage of discount applied to the booking." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 99 + strictly: false + + - name: discount_amount_in_local_currency + data_type: numeric + description: "Amount of discount in local currency applied to the booking." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 10000000 + strictly: false + + - name: fee_after_discount_in_local_currency + data_type: numeric + description: "Total fee in local currency after applying the discount." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 10000000 + strictly: true + + - name: invoice_date_utc + data_type: date + description: "Date to consider for the invoice." + tests: + - not_null + + - name: user_email + data_type: text + description: "Email address of the user associated with the booking." + + - name: company_name + data_type: text + description: "Name of the company associated with the booking." + + - name: property_manager_name + data_type: text + description: "Name of the property manager." + + - name: property_manager_email + data_type: text + description: "Email address of the property manager." + + - name: listing_name + data_type: text + description: "Name of the listing." + + - name: listing_address + data_type: text + description: "Address of the listing." + + - name: listing_town + data_type: text + description: "Town where the listing is located." + + - name: listing_country + data_type: text + description: "Country code where the listing is located." + + - name: listing_postcode + data_type: text + description: "Postcode of the listing." + + - name: pets_allowed + data_type: boolean + description: "Indicates if pets are allowed at the listing." + + - name: status_updated_at_utc + data_type: timestamp without time zone + description: "Timestamp of the last status update for the verification." + tests: + - not_null + + - name: status_updated_date_utc + data_type: date + description: "Date of the last status update for the verification." + tests: + - not_null + + - name: updated_at_utc + data_type: timestamp without time zone + description: "Timestamp of the last update to the record." + tests: + - not_null + + - name: updated_date_utc + data_type: date + description: "Date of the last update to the record." + tests: + - not_null + + - name: creation_at_utc + data_type: timestamp without time zone + description: "Timestamp of when the reservation was created." + tests: + - not_null + + - name: creation_date_utc + data_type: date + description: "Date of when the reservation was created." + tests: + - not_null + + - name: cosmos_created_date_utc + data_type: date + description: "Date of when the verification request was created in Cosmos DB." + tests: + - not_null From c01d09d9f6d770e01f886344a985562d027e497b Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Mon, 30 Dec 2024 12:11:45 +0100 Subject: [PATCH 4/5] Addressed comments --- ...screen_and_protect__verification_fees.sql} | 53 ++++------ .../screen_and_protect/schema.yml | 100 +++--------------- 2 files changed, 31 insertions(+), 122 deletions(-) rename models/intermediate/screen_and_protect/{int_screen_and_protect__invoices.sql => int_screen_and_protect__verification_fees.sql} (93%) diff --git a/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql b/models/intermediate/screen_and_protect/int_screen_and_protect__verification_fees.sql similarity index 93% rename from models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql rename to models/intermediate/screen_and_protect/int_screen_and_protect__verification_fees.sql index 9799706..832614f 100644 --- a/models/intermediate/screen_and_protect/int_screen_and_protect__invoices.sql +++ b/models/intermediate/screen_and_protect/int_screen_and_protect__verification_fees.sql @@ -121,16 +121,6 @@ with upper(vr.protection_type) = '{{ damage_waiver }}' and upper(vr.verification_status) <> '{{ rejected_status }}' ), - bookings_with_booking_fee as ( - select * - from rejected_bookings - union all - select * - from cancelled_bookings - union all - select * - from damage_waiver_bookings - ), -- Basic Protection bookings that have been approved or flagged and are not -- cancelled. approved_or_flagged_basic_protection_bookings as ( @@ -237,6 +227,16 @@ with and vr.is_cancelled is false and vr.is_protected is true ), + bookings_with_booking_fee as ( + select * + from rejected_bookings + union all + select * + from cancelled_bookings + union all + select * + from damage_waiver_bookings + ), bookings_with_nightly_fee as ( select * from approved_or_flagged_basic_protection_bookings @@ -265,34 +265,19 @@ select vr.is_cancelled, vr.cancelled_at_utc, vr.cancelled_date_utc, - bbf.booking_fee_in_local_currency, - bnf.nightly_fee_in_local_currency, - bnf.nightly_fee_in_local_currency - * vr.number_of_nights as total_fee_in_local_currency, - bnf.discount_percentage, - bnf.nightly_fee_in_local_currency + coalesce(bnf.nightly_fee_in_local_currency, 0) * vr.number_of_nights + + coalesce(bbf.booking_fee_in_local_currency, 0) as total_fee_in_local_currency, + coalesce(bnf.discount_percentage, 0) as discount_percentage, + coalesce(bnf.nightly_fee_in_local_currency, 0) * vr.number_of_nights - * bnf.discount_percentage + * coalesce(bnf.discount_percentage, 0) / 100 as discount_amount_in_local_currency, - bnf.nightly_fee_in_local_currency + coalesce(bbf.booking_fee_in_local_currency, 0) + + coalesce(bnf.nightly_fee_in_local_currency, 0) * vr.number_of_nights - * (100 - bnf.discount_percentage) - / 100 as fee_after_discount_in_local_currency, + * (100 - coalesce(bnf.discount_percentage, 0)) + / 100 as total_fee_after_discount_in_local_currency, coalesce(bbf.invoice_date_utc, bnf.invoice_date_utc) as invoice_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 diff --git a/models/intermediate/screen_and_protect/schema.yml b/models/intermediate/screen_and_protect/schema.yml index a5fb847..aa8bb67 100644 --- a/models/intermediate/screen_and_protect/schema.yml +++ b/models/intermediate/screen_and_protect/schema.yml @@ -346,12 +346,14 @@ models: data_tests: - not_null - - name: int_screen_and_protect__invoices + - name: int_screen_and_protect__verification_fees description: | - This table contains records of invoices related to verification requests - from the Screen and Protect API. - It tracks financial details such as fees, discounts, and booking-related - metadata. + This table contains all records for verification requests + from the Screen and Protect API and their fees. + It tracks financial details such as booking fees, discounts and + some booking-related metadata. + Documentation: + https://www.notion.so/knowyourguest-superhog/Invoice-Screen-Protect-1610446ff9c980f88de6d6293b4fab03?pvs=4 columns: - name: id_verification data_type: text @@ -482,24 +484,6 @@ models: data_type: date description: "Date when the booking was canceled." - - name: booking_fee_in_local_currency - data_type: numeric - description: "Fee in local currency associated with the booking." - tests: - - dbt_expectations.expect_column_values_to_be_between: - min_value: 0 - max_value: 10000 - strictly: true - - - name: nightly_fee_in_local_currency - data_type: numeric - description: "Nightly fee in local currency for the booking." - tests: - - dbt_expectations.expect_column_values_to_be_between: - min_value: 0 - max_value: 10000 - strictly: true - - name: total_fee_in_local_currency data_type: numeric description: "Total fee in local currency, inclusive of all charges." @@ -508,6 +492,7 @@ models: min_value: 0 max_value: 10000000 strictly: true + - not_null - name: discount_percentage data_type: numeric @@ -517,6 +502,7 @@ models: min_value: 0 max_value: 99 strictly: false + - not_null - name: discount_amount_in_local_currency data_type: numeric @@ -526,8 +512,9 @@ models: min_value: 0 max_value: 10000000 strictly: false + - not_null - - name: fee_after_discount_in_local_currency + - name: total_fee_after_discount_in_local_currency data_type: numeric description: "Total fee in local currency after applying the discount." tests: @@ -535,6 +522,7 @@ models: min_value: 0 max_value: 10000000 strictly: true + - not_null - name: invoice_date_utc data_type: date @@ -542,70 +530,6 @@ models: tests: - not_null - - name: user_email - data_type: text - description: "Email address of the user associated with the booking." - - - name: company_name - data_type: text - description: "Name of the company associated with the booking." - - - name: property_manager_name - data_type: text - description: "Name of the property manager." - - - name: property_manager_email - data_type: text - description: "Email address of the property manager." - - - name: listing_name - data_type: text - description: "Name of the listing." - - - name: listing_address - data_type: text - description: "Address of the listing." - - - name: listing_town - data_type: text - description: "Town where the listing is located." - - - name: listing_country - data_type: text - description: "Country code where the listing is located." - - - name: listing_postcode - data_type: text - description: "Postcode of the listing." - - - name: pets_allowed - data_type: boolean - description: "Indicates if pets are allowed at the listing." - - - name: status_updated_at_utc - data_type: timestamp without time zone - description: "Timestamp of the last status update for the verification." - tests: - - not_null - - - name: status_updated_date_utc - data_type: date - description: "Date of the last status update for the verification." - tests: - - not_null - - - name: updated_at_utc - data_type: timestamp without time zone - description: "Timestamp of the last update to the record." - tests: - - not_null - - - name: updated_date_utc - data_type: date - description: "Date of the last update to the record." - tests: - - not_null - - name: creation_at_utc data_type: timestamp without time zone description: "Timestamp of when the reservation was created." From 67bf836621e6c1398b350001bc1bf057fd58d0d3 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Thu, 13 Feb 2025 15:28:54 +0100 Subject: [PATCH 5/5] commit wip --- .../reporting/screen_and_protect/schema.yml | 202 ++++++++++++++++++ .../screen_and_protect__verification_fees.sql | 35 +++ 2 files changed, 237 insertions(+) create mode 100644 models/reporting/screen_and_protect/screen_and_protect__verification_fees.sql diff --git a/models/reporting/screen_and_protect/schema.yml b/models/reporting/screen_and_protect/schema.yml index 9ce2f81..0e8ffb1 100644 --- a/models/reporting/screen_and_protect/schema.yml +++ b/models/reporting/screen_and_protect/schema.yml @@ -248,3 +248,205 @@ models: Date of when the verification request was created in Cosmos DB. data_tests: - not_null + + - name: screen_and_protect__verification_fees + description: | + This table contains all records for verification requests + from the Screen and Protect API and their fees. + It tracks financial details such as booking fees, discounts and + some booking-related metadata. + Documentation: + https://www.notion.so/knowyourguest-superhog/Invoice-Screen-Protect-1610446ff9c980f88de6d6293b4fab03?pvs=4 + columns: + - name: id_verification + data_type: text + description: "Unique identifier for the verification request." + tests: + - not_null + - unique + + - name: id_booking + data_type: text + description: "Unique identifier for the booking associated with the verification." + tests: + - not_null + + - name: id_user_partner + data_type: text + description: "Identifier for the partner user initiating the verification." + tests: + - not_null + + - name: id_accommodation + data_type: text + description: "Identifier for the accommodation related to the booking." + + - name: is_protected + data_type: boolean + description: "Indicates if the booking is protected or not." + + - name: protection_type + data_type: text + description: "Specific protection type for the request." + tests: + - not_null + - accepted_values: + values: + - "SCREEN & PROTECT" + - "BASIC PROTECTION" + - "STANDALONE PROTECTION" + - "DAMAGE WAIVER" + - "PET PROTECTION" + + - name: protection_starting_amount_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_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_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 + max_value: 50000000 + strictly: true + + - name: pet_protection + data_type: boolean + description: Indicates if pet protection was included. + + - name: verification_status + data_type: text + description: Outcome of the verification process. + tests: + - not_null + - accepted_values: + values: + - "APPROVED" + - "FLAGGED" + - "REJECTED" + + - name: id_currency + data_type: bigint + description: "Id of the currency, works as a foreign key to the + currency table" + tests: + - not_null + - relationships: + to: ref('stg_core__currency') + field: id_currency + + - name: checkin_date_utc + data_type: date + description: "Check-in date for the booking." + tests: + - not_null + + - name: checkout_date_utc + data_type: date + description: "Check-out date for the booking." + tests: + - not_null + + - name: number_of_nights + data_type: integer + description: Number of nights for the reservation. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 1 + + - name: is_cancelled + data_type: boolean + description: "Indicates if the booking was canceled." + + - name: cancelled_at_utc + data_type: timestamp without time zone + description: "Timestamp when the booking was canceled." + + - name: cancelled_date_utc + data_type: date + description: "Date when the booking was canceled." + + - name: total_fee_in_local_currency + data_type: numeric + description: "Total fee in local currency, inclusive of all charges." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 10000000 + strictly: true + - not_null + + - name: discount_percentage + data_type: numeric + description: "Percentage of discount applied to the booking." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 99 + strictly: false + - not_null + + - name: discount_amount_in_local_currency + data_type: numeric + description: "Amount of discount in local currency applied to the booking." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 10000000 + strictly: false + - not_null + + - name: total_fee_after_discount_in_local_currency + data_type: numeric + description: "Total fee in local currency after applying the discount." + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 10000000 + strictly: true + - not_null + + - name: invoice_date_utc + data_type: date + description: "Date to consider for the invoice." + tests: + - not_null + + - name: creation_at_utc + data_type: timestamp without time zone + description: "Timestamp of when the reservation was created." + tests: + - not_null + + - name: creation_date_utc + data_type: date + description: "Date of when the reservation was created." + tests: + - not_null + + - name: cosmos_created_date_utc + data_type: date + description: "Date of when the verification request was created in Cosmos DB." + tests: + - not_null diff --git a/models/reporting/screen_and_protect/screen_and_protect__verification_fees.sql b/models/reporting/screen_and_protect/screen_and_protect__verification_fees.sql new file mode 100644 index 0000000..2a90581 --- /dev/null +++ b/models/reporting/screen_and_protect/screen_and_protect__verification_fees.sql @@ -0,0 +1,35 @@ +with + int_screen_and_protect__verification_fees as ( + select * from {{ ref("int_screen_and_protect__verification_fees") }} + ) +select + id_verification as id_verification, + id_booking as id_booking, + id_user_partner as id_user_partner, + id_accommodation as id_accommodation, + is_protected as is_protected, + protection_type as protection_type, + protection_basic_amount_in_local_currency + as protection_basic_amount_in_local_currency, + protection_starting_amount_in_local_currency + as protection_starting_amount_in_local_currency, + protection_extended_amount_in_local_currency + as protection_extended_amount_in_local_currency, + verification_status as verification_status, + id_currency as id_currency, + checkin_date_utc as checkin_date_utc, + checkout_date_utc as checkout_date_utc, + number_of_nights as number_of_nights, + is_cancelled as is_cancelled, + cancelled_at_utc as cancelled_at_utc, + cancelled_date_utc as cancelled_date_utc, + total_fee_in_local_currency as total_fee_in_local_currency, + discount_percentage as discount_percentage, + discount_amount_in_local_currency as discount_amount_in_local_currency, + total_fee_after_discount_in_local_currency + as total_fee_after_discount_in_local_currency, + invoice_date_utc as invoice_date_utc, + creation_at_utc as creation_at_utc, + creation_date_utc as creation_date_utc, + cosmos_created_date_utc as cosmos_created_date_utc +from int_screen_and_protect__verification_fees