Merged PR 3896: S&P invoice model

# Description

New Invoice model for S&P
Quite a dense model, it needs to consider some different situations for the different Protection types, verification status and if the user has the `is_protected` flag active for it's bookings.
I leave the documentation for support to better clarify all the possible scenarios and a screenshot of how it is currently looking the model's result.
There are a couple of rename changes on other models, nothing big.
If there are any inquiries let me know.
https://www.notion.so/knowyourguest-superhog/Invoice-Screen-Protect-1610446ff9c980f88de6d6293b4fab03?pvs=4

![image.png](https://guardhog.visualstudio.com/4148d95f-4b6d-4205-bcff-e9c8e0d2ca65/_apis/git/repositories/54ac356f-aad7-46d2-b62c-e8c5b3bb8ebf/pullRequests/3896/attachments/image.png)

# Checklist

- [x] The edited models and dependants run properly with production data.
- [x] The edited models are sufficiently documented.
- [x] The edited models contain PK tests, and I've ran and passed them.
- [x] I have checked for DRY opportunities with other models and docs.
- [x] I've picked the right materialization for the affected models.

# Other

- [ ] Check if a full-refresh is required after this PR is merged.

Related work items: #25360
This commit is contained in:
Joaquin Ossa 2025-02-14 08:18:42 +00:00
commit 4b94d5f70b
7 changed files with 754 additions and 21 deletions

View file

@ -18,19 +18,20 @@ select
then true then true
else false else false
end as is_protected, 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 (au.json_document_user_data ->> 'PriceIncreaseStartDate')::date
as price_increase_start_date_utc, as price_increase_start_date_utc,
(au.json_document_user_data ->> 'MonthlyVolumeDiscount')::decimal (au.json_document_user_data ->> 'MonthlyVolumeDiscount')::decimal
as monthly_volume_discount, as monthly_volume_discount_percentage,
(au.json_document_user_data ->> 'ThresholdApprovedBookingVolume')::integer (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 (au.json_document_user_data ->> 'MonthlyVolumeDiscountStartDate')::date
as monthly_volume_discount_start_date_utc, as monthly_volume_discount_start_date_utc,
(au.json_document_user_data ->> 'MonthlyVolumeDiscountEndDate')::date (au.json_document_user_data ->> 'MonthlyVolumeDiscountEndDate')::date
as monthly_volume_discount_end_date_utc, as monthly_volume_discount_end_date_utc,
(au.json_document_user_data ->> 'MonthlyGeneralDiscount')::decimal (au.json_document_user_data ->> 'MonthlyGeneralDiscount')::decimal
as monthly_general_discount, as monthly_general_discount_percentage,
(au.json_document_user_data ->> 'MonthlyGeneralDiscountStartDate')::date (au.json_document_user_data ->> 'MonthlyGeneralDiscountStartDate')::date
as monthly_general_discount_start_date_utc, as monthly_general_discount_start_date_utc,
(au.json_document_user_data ->> 'MonthlyGeneralDiscountEndDate')::date (au.json_document_user_data ->> 'MonthlyGeneralDiscountEndDate')::date

View file

@ -4742,7 +4742,7 @@ models:
data_tests: data_tests:
- not_null - not_null
- name: price_increase - name: price_increase_percentage
data_type: numeric data_type: numeric
description: The percentage or value of the price increase description: The percentage or value of the price increase
applied to the user's account. applied to the user's account.
@ -4758,7 +4758,7 @@ models:
data_tests: data_tests:
- is_first_day_of_month - is_first_day_of_month
- name: monthly_volume_discount - name: monthly_volume_discount_percentage
data_type: numeric data_type: numeric
description: The discount percentage or value offered based on the description: The discount percentage or value offered based on the
volume of bookings achieved within a month. volume of bookings achieved within a month.
@ -4769,7 +4769,7 @@ models:
max_value: 100 max_value: 100
strictly: true strictly: true
- name: threshold_approved_booking_volume - name: threshold_approved_or_flagged_booking_volume
data_type: numeric data_type: numeric
description: The minimum number of bookings required to qualify for description: The minimum number of bookings required to qualify for
the monthly volume discount. the monthly volume discount.
@ -4792,7 +4792,7 @@ models:
data_tests: data_tests:
- is_last_day_of_month - is_last_day_of_month
- name: monthly_general_discount - name: monthly_general_discount_percentage
data_type: numeric data_type: numeric
description: The general discount percentage or value applied to all description: The general discount percentage or value applied to all
bookings within the applicable period. bookings within the applicable period.

View file

@ -0,0 +1,286 @@
{% 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 cancelled_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,
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_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 }}
and vr.is_protected is true
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_or_flagged_booking_volume
and adt.is_monthly_volume_discount_on = 1
then 1
else 0
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
and upper(vr.protection_type) <> '{{ damage_waiver }}'
)
),
-- 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 }}'
),
-- 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,
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
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,
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
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,
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
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_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
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,
vr.id_booking,
vr.id_user_partner,
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,
vr.checkout_date_utc,
vr.number_of_nights,
vr.is_cancelled,
vr.cancelled_at_utc,
vr.cancelled_date_utc,
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
* coalesce(bnf.discount_percentage, 0)
/ 100 as discount_amount_in_local_currency,
coalesce(bbf.booking_fee_in_local_currency, 0)
+ coalesce(bnf.nightly_fee_in_local_currency, 0)
* vr.number_of_nights
* (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.creation_at_utc,
vr.creation_date_utc,
vr.cosmos_created_date_utc
from int_screen_and_protect__verification_requests vr
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

View file

@ -19,13 +19,13 @@ select
vr.pet_protection, vr.pet_protection,
vr.verification_status, vr.verification_status,
vr.verification_status_reason, vr.verification_status_reason,
spu.price_increase, spu.price_increase_percentage,
spu.price_increase_start_date_utc, spu.price_increase_start_date_utc,
spu.monthly_volume_discount, spu.monthly_volume_discount_percentage,
spu.threshold_approved_booking_volume, spu.threshold_approved_or_flagged_booking_volume,
spu.monthly_volume_discount_start_date_utc, spu.monthly_volume_discount_start_date_utc,
spu.monthly_volume_discount_end_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_start_date_utc,
spu.monthly_general_discount_end_date_utc, spu.monthly_general_discount_end_date_utc,
vr.email_flag, vr.email_flag,

View file

@ -9,8 +9,8 @@ models:
data_tests: data_tests:
- at_least_one_null: - at_least_one_null:
columns: columns:
- monthly_volume_discount - monthly_volume_discount_percentage
- monthly_general_discount - monthly_general_discount_percentage
columns: columns:
- name: id_verification - name: id_verification
data_type: text data_type: text
@ -113,7 +113,7 @@ models:
- "FLAGGED" - "FLAGGED"
- "REJECTED" - "REJECTED"
- name: price_increase - name: price_increase_percentage
data_type: numeric data_type: numeric
description: The percentage or value of the price increase description: The percentage or value of the price increase
applied to the user's account. applied to the user's account.
@ -129,7 +129,7 @@ models:
data_tests: data_tests:
- is_first_day_of_month - is_first_day_of_month
- name: monthly_volume_discount - name: monthly_volume_discount_percentage
data_type: numeric data_type: numeric
description: The discount percentage or value offered based on the description: The discount percentage or value offered based on the
volume of bookings achieved within a month. volume of bookings achieved within a month.
@ -140,7 +140,7 @@ models:
max_value: 100 max_value: 100
strictly: true strictly: true
- name: threshold_approved_booking_volume - name: threshold_approved_or_flagged_booking_volume
data_type: numeric data_type: numeric
description: The minimum number of bookings required to qualify for description: The minimum number of bookings required to qualify for
the monthly volume discount. the monthly volume discount.
@ -163,7 +163,7 @@ models:
data_tests: data_tests:
- is_last_day_of_month - is_last_day_of_month
- name: monthly_general_discount - name: monthly_general_discount_percentage
data_type: numeric data_type: numeric
description: The general discount percentage or value applied to all description: The general discount percentage or value applied to all
bookings within the applicable period. bookings within the applicable period.
@ -215,15 +215,22 @@ models:
- name: checkin_date_utc - name: checkin_date_utc
data_type: date data_type: date
description: Check-in date for the booking. description: "Check-in date for the booking."
tests:
- not_null
- name: checkout_date_utc - name: checkout_date_utc
data_type: date data_type: date
description: Check-out date for the booking. description: "Check-out date for the booking."
tests:
- not_null
- name: number_of_nights - name: number_of_nights
data_type: integer 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 - name: is_cancelled
data_type: boolean data_type: boolean
@ -338,3 +345,205 @@ models:
Date of when the verification request was created in Cosmos DB. Date of when the verification request was created in Cosmos DB.
data_tests: data_tests:
- not_null - not_null
- name: int_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

View file

@ -248,3 +248,205 @@ models:
Date of when the verification request was created in Cosmos DB. Date of when the verification request was created in Cosmos DB.
data_tests: data_tests:
- not_null - 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

View file

@ -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