Completed schema

This commit is contained in:
Joaquin Ossa 2024-12-23 16:20:12 +01:00
parent 9a4c7a312d
commit 60ebb13f1d
2 changed files with 319 additions and 16 deletions

View file

@ -85,7 +85,10 @@ with
from int_screen_and_protect__verification_requests vr from int_screen_and_protect__verification_requests vr
where where
upper(vr.verification_status) = '{{ rejected_status }}' 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 -- All cancelled bookings, excluding those with damage waiver protection or that
-- have been charged the rejected fee -- have been charged the rejected fee
@ -138,9 +141,13 @@ with
then bp.long_stay_fee_in_local_currency then bp.long_stay_fee_in_local_currency
else bp.short_stay_fee_in_local_currency else bp.short_stay_fee_in_local_currency
end as nightly_fee_in_local_currency, end as nightly_fee_in_local_currency,
vr.monthly_volume_discount_percentage * ad.is_monthly_volume_discount_active coalesce(
+ vr.monthly_general_discount_percentage vr.monthly_volume_discount_percentage
* ad.is_monthly_general_discount_active as 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 vr.checkout_date_utc as invoice_date_utc
from int_screen_and_protect__verification_requests vr from int_screen_and_protect__verification_requests vr
inner join inner join
@ -168,9 +175,13 @@ with
then sp.long_stay_fee_in_local_currency then sp.long_stay_fee_in_local_currency
else sp.short_stay_fee_in_local_currency else sp.short_stay_fee_in_local_currency
end as nightly_fee_in_local_currency, end as nightly_fee_in_local_currency,
vr.monthly_volume_discount_percentage * ad.is_monthly_volume_discount_active coalesce(
+ vr.monthly_general_discount_percentage vr.monthly_volume_discount_percentage
* ad.is_monthly_general_discount_active as 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 vr.checkout_date_utc as invoice_date_utc
from int_screen_and_protect__verification_requests vr from int_screen_and_protect__verification_requests vr
inner join inner join
@ -200,9 +211,13 @@ with
then sp.long_stay_fee_in_local_currency then sp.long_stay_fee_in_local_currency
else sp.short_stay_fee_in_local_currency else sp.short_stay_fee_in_local_currency
end as nightly_fee_in_local_currency, end as nightly_fee_in_local_currency,
vr.monthly_volume_discount_percentage * ad.is_monthly_volume_discount_active coalesce(
+ vr.monthly_general_discount_percentage vr.monthly_volume_discount_percentage
* ad.is_monthly_general_discount_active as 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 vr.checkout_date_utc as invoice_date_utc
from int_screen_and_protect__verification_requests vr from int_screen_and_protect__verification_requests vr
inner join inner join
@ -239,6 +254,9 @@ select
vr.id_accommodation, vr.id_accommodation,
vr.is_protected, vr.is_protected,
vr.protection_type, 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.verification_status,
vr.id_currency, vr.id_currency,
vr.checkin_date_utc, vr.checkin_date_utc,
@ -258,7 +276,7 @@ select
/ 100 as discount_amount_in_local_currency, / 100 as discount_amount_in_local_currency,
bnf.nightly_fee_in_local_currency bnf.nightly_fee_in_local_currency
* vr.number_of_nights * vr.number_of_nights
* (1 - bnf.discount_percentage) * (100 - bnf.discount_percentage)
/ 100 as fee_after_discount_in_local_currency, / 100 as fee_after_discount_in_local_currency,
coalesce(bbf.invoice_date_utc, bnf.invoice_date_utc) as invoice_date_utc, coalesce(bbf.invoice_date_utc, bnf.invoice_date_utc) as invoice_date_utc,
vr.user_email, vr.user_email,

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
@ -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,281 @@ 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__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