Merged PR 5047: First API unified version of Verifications
# Description Creates a first unified version of API verifications. This is a very simple model as it aims to capture the minimal essence of Verifications in a unified view. Any very-in-depth-API-specific detail is not available here. Additionally, I propagated the Check-in date in the Athena model. This is needed for API Bookings KPIs future models. # 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. **Currently as a view, despite it's 70k records. If this grows we could consider other materialisations** # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #29374
This commit is contained in:
parent
54e20e00d5
commit
ca2311d935
4 changed files with 199 additions and 0 deletions
|
|
@ -28,6 +28,7 @@ select
|
||||||
else 0
|
else 0
|
||||||
end as ok_status_fee_in_gbp,
|
end as ok_status_fee_in_gbp,
|
||||||
v.created_date_utc,
|
v.created_date_utc,
|
||||||
|
v.checkin_date_utc,
|
||||||
v.checkout_date_utc
|
v.checkout_date_utc
|
||||||
from ranked_verifications v
|
from ranked_verifications v
|
||||||
left join
|
left join
|
||||||
|
|
|
||||||
|
|
@ -248,6 +248,12 @@ models:
|
||||||
data_tests:
|
data_tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: checkin_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: "Date of checkin for the booking"
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
- name: checkout_date_utc
|
- name: checkout_date_utc
|
||||||
data_type: date
|
data_type: date
|
||||||
description: "Date of checkout for the booking"
|
description: "Date of checkout for the booking"
|
||||||
|
|
|
||||||
81
models/intermediate/cross/int_unified_api_verifications.sql
Normal file
81
models/intermediate/cross/int_unified_api_verifications.sql
Normal file
|
|
@ -0,0 +1,81 @@
|
||||||
|
{% set guesty_id_deal = "17814677813" %}
|
||||||
|
with
|
||||||
|
int_edeposit__verification_fees as (
|
||||||
|
select * from {{ ref("int_edeposit__verification_fees") }}
|
||||||
|
),
|
||||||
|
int_athena__verifications_with_fees as (
|
||||||
|
select * from {{ ref("int_athena__verifications_with_fees") }}
|
||||||
|
),
|
||||||
|
int_check_in_hero__checkins as (
|
||||||
|
select * from {{ ref("int_check_in_hero__checkins") }}
|
||||||
|
),
|
||||||
|
int_screen_and_protect__verification_fees as (
|
||||||
|
select * from {{ ref("int_screen_and_protect__verification_fees") }}
|
||||||
|
)
|
||||||
|
select
|
||||||
|
'E-DEPOSIT' as api_source,
|
||||||
|
id_verification,
|
||||||
|
id_booking,
|
||||||
|
id_deal,
|
||||||
|
verification_status,
|
||||||
|
checkin_date_utc as check_in_date_utc,
|
||||||
|
checkout_date_utc as check_out_date_utc,
|
||||||
|
created_date_utc,
|
||||||
|
checkout_date_utc as billable_date_utc,
|
||||||
|
is_cancelled,
|
||||||
|
case
|
||||||
|
when count(1) over (partition by id_booking) > 1 then true else false
|
||||||
|
end as is_duplicate_booking,
|
||||||
|
count(1) over (partition by id_booking) as booking_is_duplicated_n_times
|
||||||
|
from int_edeposit__verification_fees
|
||||||
|
union all
|
||||||
|
select
|
||||||
|
'ATHENA' as api_source,
|
||||||
|
id_verification,
|
||||||
|
id_booking,
|
||||||
|
'{{guesty_id_deal}}' as id_deal,
|
||||||
|
verification_status,
|
||||||
|
checkin_date_utc as check_in_date_utc,
|
||||||
|
checkout_date_utc as check_out_date_utc,
|
||||||
|
created_date_utc,
|
||||||
|
checkout_date_utc as billable_date_utc,
|
||||||
|
is_cancelled,
|
||||||
|
case
|
||||||
|
when count(1) over (partition by id_booking) > 1 then true else false
|
||||||
|
end as is_duplicate_booking,
|
||||||
|
count(1) over (partition by id_booking) as booking_is_duplicated_n_times
|
||||||
|
from int_athena__verifications_with_fees
|
||||||
|
union all
|
||||||
|
select
|
||||||
|
'CHECK_IN_HERO' as api_source,
|
||||||
|
id_record as id_verification,
|
||||||
|
id_reservation as id_booking,
|
||||||
|
id_deal,
|
||||||
|
null as verification_status,
|
||||||
|
checkin_date_utc as check_in_date_utc,
|
||||||
|
checkout_date_utc as check_out_date_utc,
|
||||||
|
created_date_utc,
|
||||||
|
created_date_utc as billable_date_utc,
|
||||||
|
null as is_cancelled,
|
||||||
|
case
|
||||||
|
when count(1) over (partition by id_reservation) > 1 then true else false
|
||||||
|
end as is_duplicate_booking,
|
||||||
|
count(1) over (partition by id_reservation) as booking_is_duplicated_n_times
|
||||||
|
from int_check_in_hero__checkins
|
||||||
|
union all
|
||||||
|
select
|
||||||
|
'SCREEN_AND_PROTECT' as api_source,
|
||||||
|
id_verification,
|
||||||
|
id_booking,
|
||||||
|
id_deal,
|
||||||
|
verification_status,
|
||||||
|
checkin_date_utc as check_in_date_utc,
|
||||||
|
checkout_date_utc as check_out_date_utc,
|
||||||
|
creation_date_utc as created_date_utc,
|
||||||
|
invoice_date_utc as billable_date_utc,
|
||||||
|
is_cancelled,
|
||||||
|
case
|
||||||
|
when count(1) over (partition by id_booking) > 1 then true else false
|
||||||
|
end as is_duplicate_booking,
|
||||||
|
count(1) over (partition by id_booking) as booking_is_duplicated_n_times
|
||||||
|
from int_screen_and_protect__verification_fees
|
||||||
|
|
@ -3393,3 +3393,114 @@ models:
|
||||||
flag.
|
flag.
|
||||||
data_tests:
|
data_tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: int_unified_api_verifications
|
||||||
|
description: |
|
||||||
|
This model unifies the API verifications data from different sources
|
||||||
|
(Athena, E-Deposit, Check In Hero, Screen & Protect) into a single table.
|
||||||
|
It also includes information regarding the Booking.
|
||||||
|
Since the data is coming from different sources, the model provides a
|
||||||
|
minimal set of columns that are relevant for this unified view.
|
||||||
|
data_tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- id_verification
|
||||||
|
- api_source
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: api_source
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Source of the API verification (e.g., ATHENA, E-DEPOSIT, CHECK_IN_HERO,
|
||||||
|
SCREEN_AND_PROTECT). This field is mandatory and cannot be null.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- ATHENA
|
||||||
|
- E-DEPOSIT
|
||||||
|
- CHECK_IN_HERO
|
||||||
|
- SCREEN_AND_PROTECT
|
||||||
|
|
||||||
|
- name: id_verification
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Unique ID for a verification. This ID is generated by each API,
|
||||||
|
thus it can potentially be duplicated across different sources.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: id_booking
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Unique ID for a booking. It can be duplicated, as
|
||||||
|
reflected in the field "is_duplicate_booking".
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: id_deal
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Unique ID for a deal, or account.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: verification_status
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Status of the verification. It can be null
|
||||||
|
for some sources. Status depends on the source.
|
||||||
|
|
||||||
|
- name: check_in_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Check-in date in UTC. It cannot be null.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: check_out_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Check-out date in UTC. It cannot be null.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: created_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Created date in UTC. It cannot be null.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: billable_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Billable date in UTC. This is the point in time in
|
||||||
|
which the verification can be billed. It cannot be null.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: is_cancelled
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Flag indicating if the booking linked to the verification
|
||||||
|
is cancelled or not. It can be null for some sources.
|
||||||
|
|
||||||
|
- name: is_duplicate_booking
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Flag indicating if the booking linked to the verification
|
||||||
|
is a duplicate or not. It cannot be null.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: booking_is_duplicated_n_times
|
||||||
|
data_type: integer
|
||||||
|
description: |
|
||||||
|
Number of times the booking linked to the verification
|
||||||
|
is duplicated. It cannot be null.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 1
|
||||||
|
strictly: false
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue