Merge branch 'master' of ssh.dev.azure.com:v3/guardhog/Data/data-dwh-dbt-project

This commit is contained in:
Pablo Martin 2024-11-20 10:09:08 +01:00
commit d73ca6555c
4 changed files with 395 additions and 3 deletions

View file

@ -0,0 +1,108 @@
{{ config(materialized="table", unique_key=["id_booking"]) }}
with
int_core__booking_to_service as (
select * from {{ ref("int_core__booking_to_service") }}
),
int_core__booking_service_detail as (
select * from {{ ref("int_core__booking_service_detail") }}
)
select
bts.id_booking,
bts.id_verification_request,
bts.id_deal,
bts.id_user_host,
bts.id_user_guest,
bts.booking_status,
bts.booking_created_at_utc,
bts.booking_updated_at_utc,
bts.booking_check_in_at_utc,
bts.booking_check_out_at_utc,
bts.host_currency_code,
bts.is_user_in_new_dash,
bts.new_dash_version,
bts.user_in_new_dash_since_timestamp_at_utc,
sum(bsd.service_total_price_in_gbp) as booking_total_price_in_gbp,
min(bsd.service_charge_date_utc) as first_service_charge_date_utc,
max(bsd.service_charge_date_utc) as last_service_charge_date_utc,
min(bsd.service_detail_created_at_utc) as first_service_detail_created_at_utc,
max(bsd.service_detail_created_at_utc) as last_service_detail_created_at_utc,
max(bsd.service_detail_updated_at_utc) as last_service_detail_updated_at_utc,
count(distinct bsd.id_booking_service_detail) as number_of_applied_services,
count(
distinct case
when bsd.is_paid_service then bsd.id_booking_service_detail else null
end
) as number_of_applied_paid_services,
count(
distinct case
when bsd.is_upgraded_service then bsd.id_booking_service_detail else null
end
) as number_of_applied_upgraded_services,
case
when sum(case when bsd.is_missing_currency_code then 1 else 0 end) > 0
then true
else false
end as is_missing_currency_code_in_service_detail,
case
when sum(case when bsd.is_booking_cancelled then 1 else 0 end) > 0
then true
else false
end as is_booking_cancelled,
case
when sum(case when bsd.is_paid_service then 1 else 0 end) > 0
then true
else false
end as has_paid_services,
case
when sum(case when bsd.is_upgraded_service then 1 else 0 end) > 0
then true
else false
end as has_upgraded_services,
case
when
sum(case when bsd.service_business_type = 'SCREENING' then 1 else 0 end) > 0
then true
else false
end as has_screening_service_business_type,
case
when
sum(
case
when bsd.service_business_type = 'DEPOSIT_MANAGEMENT' then 1 else 0
end
)
> 0
then true
else false
end as has_deposit_management_service_business_type,
case
when
sum(case when bsd.service_business_type = 'PROTECTION' then 1 else 0 end)
> 0
then true
else false
end as has_protection_service_business_type,
case when bts.id_deal is null then true else false end as is_missing_id_deal,
case
when bts.host_currency_code is null then true else false
end as is_missing_host_currency_code
from int_core__booking_to_service bts
inner join
int_core__booking_service_detail bsd
on bts.id_booking_service_detail = bsd.id_booking_service_detail
group by
bts.id_booking,
bts.id_verification_request,
bts.id_deal,
bts.id_user_host,
bts.id_user_guest,
bts.booking_status,
bts.booking_created_at_utc,
bts.booking_updated_at_utc,
bts.booking_check_in_at_utc,
bts.booking_check_out_at_utc,
bts.host_currency_code,
bts.is_user_in_new_dash,
bts.new_dash_version,
bts.user_in_new_dash_since_timestamp_at_utc

View file

@ -9,10 +9,12 @@ with
int_core__user_host as (select * from {{ ref("int_core__user_host") }})
select
bv.id_booking,
b.id_verification_request,
bvts.id_booking_view_to_service as id_booking_service_detail,
bvts.id_verification,
bvts.id_product_service,
bvts.id_protection_plan,
uh.id_deal,
b.id_user_host,
b.id_user_guest,
bvts.service_name,
@ -26,6 +28,9 @@ select
b.check_in_at_utc as booking_check_in_at_utc,
b.check_out_at_utc as booking_check_out_at_utc,
uh.account_currency_iso4217 as host_currency_code,
uh.is_user_in_new_dash,
uh.new_dash_version,
uh.user_in_new_dash_since_timestamp_at_utc,
case
when uh.account_currency_iso4217 is null then true else false
end as is_missing_host_currency_code,

View file

@ -1,4 +1,4 @@
{% set host_roles = "('EDEPOSIT', 'HOST', 'KNOWYOURGUEST', 'PLATFORM', 'PROPERTYVERIFICATIONMANAGER', 'SCREENINGAPI')" %}
{% set host_roles = "('EDEPOSIT', 'HOST', 'KNOWYOURGUEST', 'PLATFORM', 'PROPERTYVERIFICATIONMANAGER', 'SCREENINGAPI', 'CANCELLATIONAPI', 'CHECKINHEROAPI','SCREENANDPROTECTAPI')" %}
{% set kyg_claim_types = "('KYGREGISTRATIONSIGNUPTYPE','KYGREGISTRATIONINTEGRATIONTYPENAME','KYGMVP', 'NEWDASHVERSION')" %}
{{ config(materialized="table", unique_key="id_user_host") }}

View file

@ -1694,6 +1694,7 @@ models:
- PropertyVerificationManager
- CheckInHeroApi
- CancellationApi
- ScreenAndProtectAPI
tests:
- dbt_utils.unique_combination_of_columns:
@ -1725,6 +1726,7 @@ models:
- PropertyVerificationManager
- CheckInHeroApi
- CancellationApi
- ScreenAndProtectApi
- name: int_core__user_host
description: |
@ -1740,10 +1742,14 @@ models:
- KnowYourGuest
- ScreeningAPI
- PropertyVerificationManager
- CancellationApi
- CheckInHeroApi
- ScreenAndProtectApi
Additionally, any user that has any of these claim types will be considered as a Host:
- KygRegistrationSignUpType
- KygRegistrationIntegrationTypeName
- KygMvp
- NewDashVersion
Lastly, in case a user satisfies multiple conditions, it will only appear once in this table.
columns:
@ -1882,7 +1888,7 @@ models:
data_type: timestamp
description: |
For users that are in New Dash, the effective date since
these users can be considered in New Dash. It the user
these users can be considered in New Dash. If the user
has moved from Old Dash, it will be the new_dash_move_at_utc.
If not, it will correspond to the joined_at_utc.
@ -1934,7 +1940,7 @@ models:
data_type: timestamp
description: |
For users that are in New Dash, the effective date since
these users can be considered in New Dash. It the user
these users can be considered in New Dash. If the user
has moved from Old Dash, it will be the new_dash_move_at_utc.
If not, it will correspond to the joined_at_utc.
@ -3206,6 +3212,12 @@ models:
- not_null
- unique
- name: id_verification_request
data_type: bigint
description:
The identifier of the verification request. It acts as Foreign Key to
Verification Request table. It can be null.
- name: id_verification
data_type: bigint
description: |
@ -3224,6 +3236,11 @@ models:
The identifier of the protection plan, aka protection service. It acts as
Foreign Key to Product Plan table. It can be null.
- name: id_deal
data_type: string
description: |
Unique identifier of the account. It can be null.
- name: id_user_host
data_type: string
description: |
@ -3314,6 +3331,29 @@ models:
Iso 4217 currency code for the account of the Host.
It can be null.
- name: is_user_in_new_dash
data_type: boolean
description: |
Flag to determine if this user host is in New Dash or not.
tests:
- not_null
- name: new_dash_version
data_type: string
description: |
For users that are in New Dash, specifies the New Dash Version
in which these users were moved or joined. It can be null if
the user is not in new dash.
- name: user_in_new_dash_since_timestamp_at_utc
data_type: timestamp
description: |
For users that are in New Dash, the effective date since
these users can be considered in New Dash. If the user
has moved from Old Dash, it will be the new_dash_move_at_utc.
If not, it will correspond to the joined_at_utc. It can be null
if the user is not in new dash.
- name: is_missing_host_currency_code
data_type: boolean
description: |
@ -3573,3 +3613,242 @@ models:
meaning, it's not a Basic Screening.
tests:
- not_null
- name: int_core__booking_summary
description: |
This model contains enriched information aggregated at Booking level regarding
the services that are applied within a Booking.
Specifically, contains both Booking and Services attributes (aggregated), as well
as the total price in GBP at this specific moment in time. In other words,
it's the snapshot of the current status of the Booking.
It's a subset of all bookings since it only applies to bookings that come from
hosts that have been migrated into the New Dash or New Pricing.
tests:
- dbt_expectations.expect_column_pair_values_A_to_be_greater_than_B:
column_A: booking_check_out_at_utc
column_B: booking_check_in_at_utc
or_equal: True
- dbt_expectations.expect_column_pair_values_A_to_be_greater_than_B:
column_A: number_of_applied_services
column_B: number_of_applied_paid_services
or_equal: True
- dbt_expectations.expect_column_pair_values_A_to_be_greater_than_B:
column_A: number_of_applied_services
column_B: number_of_applied_upgraded_services
or_equal: True
columns:
- name: id_booking
data_type: bigint
description: |
The identifier of the booking. Acts as Primary Key to this table.
Cannot be null.
tests:
- not_null
- unique
- name: id_verification_request
data_type: bigint
description:
The identifier of the verification request. It acts as Foreign Key to
Verification Request table. It can be null.
- name: id_deal
data_type: string
description: |
Unique identifier of the account. It can be null.
- name: id_user_host
data_type: string
description: |
Unique identifier of the user that acts as a Host. Cannot be null.
tests:
- not_null
- name: id_user_guest
data_type: string
description: |
Unique identifier of the user that acts as a Guest.
Can be null if Superhog does not interact with the Guest.
- name: booking_status
data_type: string
description: |
The current status of the booking. Cannot be null.
tests:
- not_null
- name: booking_created_at_utc
data_type: timestamp
description: |
Timestamp of when the Booking record was created in the Backend.
Cannot be null.
tests:
- not_null
- name: booking_updated_at_utc
data_type: timestamp
description: |
Timestamp of when the Booking record was last updated in the Backend.
Cannot be null.
tests:
- not_null
- name: booking_check_in_at_utc
data_type: timestamp
description: |
Timestamp of the Check-in of the Booking.
Cannot be null.
tests:
- not_null
- name: booking_check_out_at_utc
data_type: timestamp
description: |
Timestamp of the Check-out of the Booking.
Cannot be null.
tests:
- not_null
- name: host_currency_code
data_type: string
description: |
Iso 4217 currency code for the account of the Host.
It can be null.
- name: is_user_in_new_dash
data_type: boolean
description: |
Flag to determine if this user host is in New Dash or not.
tests:
- not_null
- name: new_dash_version
data_type: string
description: |
For users that are in New Dash, specifies the New Dash Version
in which these users were moved or joined. It can be null if
the user is not in new dash.
- name: user_in_new_dash_since_timestamp_at_utc
data_type: timestamp
description: |
For users that are in New Dash, the effective date since
these users can be considered in New Dash. If the user
has moved from Old Dash, it will be the new_dash_move_at_utc.
If not, it will correspond to the joined_at_utc. It can be null
if the user is not in new dash.
- name: booking_total_price_in_gbp
data_type: decimal
description: |
Identifies the current total price of the booking by adding up the
prices of each service applied to this booking, converted in GBP.
Can be null. Can vary over time depending on the service status,
payments, etc, as well as it can vary over time until the charge
date due to the currency rate estimation in the future.
- name: first_service_charge_date_utc
data_type: date
description: |
Identifies the first moment in time in which the first
service applied to this booking is charged.
- name: last_service_charge_date_utc
data_type: date
description: |
Identifies the last moment in time in which the last
service applied to this booking is charged.
- name: first_service_detail_created_at_utc
data_type: timestamp
description: |
Timestamp corresponding to the first creation of a Service
record applied to this Booking, according to the Backend.
tests:
- not_null
- name: last_service_detail_created_at_utc
data_type: timestamp
description: |
Timestamp corresponding to the latest creation of a Service
record applied to this Booking, according to the Backend.
tests:
- not_null
- name: last_service_detail_updated_at_utc
data_type: timestamp
description: |
Timestamp corresponding to the latest update on any Service
record applied to this Booking, according to the Backend.
tests:
- not_null
- name: number_of_applied_services
data_type: integer
description: |
Total number of Services applied to this Booking.
- name: number_of_applied_paid_services
data_type: integer
description: |
Total number of Services that require a monetary
income to Superhog applied to this Booking.
- name: number_of_applied_upgraded_services
data_type: integer
description: |
Total number of Services different from Basic Screening
applied to this Booking.
- name: is_missing_currency_code_in_service_detail
data_type: boolean
description: |
Flag to identify if the currency code is missing in any
Booking Service Detail record for this Booking.
- name: is_booking_cancelled
data_type: boolean
description: |
Flag to identify if the booking has been cancelled or not.
- name: has_paid_services
data_type: boolean
description: |
Flag to identify if the booking has any paid service or not.
- name: has_upgraded_services
data_type: boolean
description: |
Flag to identify if the booking has any service different from
Basic Screening or not.
- name: has_screening_service_business_type
data_type: boolean
description: |
Flag to identify if the booking contains any Screening service
or not.
- name: has_deposit_management_service_business_type
data_type: boolean
description: |
Flag to identify if the booking contains any Deposit
Management service or not.
- name: has_protection_service_business_type
data_type: boolean
description: |
Flag to identify if the booking contains any Protection
service or not.
- name: is_missing_id_deal
data_type: boolean
description: |
Flag to identify if the Host for this booking is missing
the Id Deal or not.
- name: is_missing_host_currency_code
data_type: boolean
description: |
Flag to identify if the Host for this booking is missing
the currency code or not.