Merged PR 4335: Rework new dash attribution using booking summary
# Description Changes: * On Created and Check Out Bookings daily models, the determination of New Dash bookings now uses `int_core__booking_summary`. This does not change the output, but will be more consistent for other KPIs. * Adds the categorisation of `dash_source` in all daily metric models that depend on Verification Requests (Guest Journeys). This affects GJ Created, GJ Started, GJ Completed, GJ w. Payment and Guest Payments. Note that the next aggregations (monthly, mtd, agg_monthly, agg_mtd) are not created yet. This will be done in a separated PR. # 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: #27356
This commit is contained in:
parent
aa04b1a84f
commit
b471b64d9c
8 changed files with 129 additions and 20 deletions
|
|
@ -4,7 +4,7 @@ select
|
|||
icb.check_out_date_utc as date,
|
||||
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when icbtpb.id_booking is not null then 'New Dash' else 'Old Dash'
|
||||
when icbs.id_booking is not null then 'New Dash' else 'Old Dash'
|
||||
end as dash_source,
|
||||
-- Dimensions --
|
||||
coalesce(
|
||||
|
|
@ -38,7 +38,9 @@ left join
|
|||
on icuh.id_deal = icmas.id_deal
|
||||
and icb.check_out_date_utc = icmas.date
|
||||
left join
|
||||
{{ ref("int_core__booking_to_product_bundle") }} as icbtpb
|
||||
on icb.id_booking = icbtpb.id_booking
|
||||
{{ ref("int_core__booking_summary") }} as icbs
|
||||
on icb.id_booking = icbs.id_booking
|
||||
and icbs.is_user_in_new_dash = true
|
||||
and icbs.is_missing_id_deal = false
|
||||
where icb.is_duplicate_booking = false
|
||||
group by 1, 2, 3, 4, 5
|
||||
|
|
|
|||
|
|
@ -1,8 +1,11 @@
|
|||
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
||||
{{ config(materialized="table", unique_key=["date", "id_deal", "dash_source"]) }}
|
||||
select
|
||||
-- Unique Key --
|
||||
icvr.verification_estimated_completed_date_utc as date,
|
||||
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when icbs.id_booking is not null then 'New Dash' else 'Old Dash'
|
||||
end as dash_source,
|
||||
-- Dimensions --
|
||||
coalesce(
|
||||
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||
|
|
@ -20,5 +23,10 @@ left join
|
|||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||
on icuh.id_deal = icmas.id_deal
|
||||
and icvr.verification_estimated_completed_date_utc = icmas.date
|
||||
left join
|
||||
{{ ref("int_core__booking_summary") }} as icbs
|
||||
on icvr.id_verification_request = icbs.id_verification_request
|
||||
and icbs.is_user_in_new_dash = true
|
||||
and icbs.is_missing_id_deal = false
|
||||
where icvr.verification_estimated_completed_date_utc is not null
|
||||
group by 1, 2, 3, 4
|
||||
group by 1, 2, 3, 4, 5
|
||||
|
|
|
|||
|
|
@ -4,7 +4,7 @@ select
|
|||
icb.created_date_utc as date,
|
||||
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when icbtpb.id_booking is not null then 'New Dash' else 'Old Dash'
|
||||
when icbs.id_booking is not null then 'New Dash' else 'Old Dash'
|
||||
end as dash_source,
|
||||
-- Dimensions --
|
||||
coalesce(
|
||||
|
|
@ -38,7 +38,9 @@ left join
|
|||
on icuh.id_deal = icmas.id_deal
|
||||
and icb.created_date_utc = icmas.date
|
||||
left join
|
||||
{{ ref("int_core__booking_to_product_bundle") }} as icbtpb
|
||||
on icb.id_booking = icbtpb.id_booking
|
||||
{{ ref("int_core__booking_summary") }} as icbs
|
||||
on icb.id_booking = icbs.id_booking
|
||||
and icbs.is_user_in_new_dash = true
|
||||
and icbs.is_missing_id_deal = false
|
||||
where icb.is_duplicate_booking = false
|
||||
group by 1, 2, 3, 4, 5
|
||||
|
|
|
|||
|
|
@ -1,8 +1,11 @@
|
|||
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
||||
{{ config(materialized="table", unique_key=["date", "id_deal", "dash_source"]) }}
|
||||
select
|
||||
-- Unique Key --
|
||||
icvr.created_date_utc as date,
|
||||
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when icbs.id_booking is not null then 'New Dash' else 'Old Dash'
|
||||
end as dash_source,
|
||||
-- Dimensions --
|
||||
coalesce(
|
||||
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||
|
|
@ -20,4 +23,9 @@ left join
|
|||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||
on icuh.id_deal = icmas.id_deal
|
||||
and icvr.created_date_utc = icmas.date
|
||||
group by 1, 2, 3, 4
|
||||
left join
|
||||
{{ ref("int_core__booking_summary") }} as icbs
|
||||
on icvr.id_verification_request = icbs.id_verification_request
|
||||
and icbs.is_user_in_new_dash = true
|
||||
and icbs.is_missing_id_deal = false
|
||||
group by 1, 2, 3, 4, 5
|
||||
|
|
|
|||
|
|
@ -14,6 +14,9 @@ select
|
|||
-- Unique Key --
|
||||
p.first_payment_paid_date_utc as date,
|
||||
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when icbs.id_booking is not null then 'New Dash' else 'Old Dash'
|
||||
end as dash_source,
|
||||
-- Dimensions --
|
||||
coalesce(
|
||||
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||
|
|
@ -34,4 +37,9 @@ left join
|
|||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||
on icuh.id_deal = icmas.id_deal
|
||||
and p.first_payment_paid_date_utc = icmas.date
|
||||
group by 1, 2, 3, 4
|
||||
left join
|
||||
{{ ref("int_core__booking_summary") }} as icbs
|
||||
on p.id_verification_request = icbs.id_verification_request
|
||||
and icbs.is_user_in_new_dash = true
|
||||
and icbs.is_missing_id_deal = false
|
||||
group by 1, 2, 3, 4, 5
|
||||
|
|
|
|||
|
|
@ -3,12 +3,20 @@
|
|||
{% set checkin_cover_fees_verification_payment_type_items = "('CHECKINCOVER')" %}
|
||||
{% set id_check = "('GOVERNMENTID')" %}
|
||||
|
||||
{{ config(materialized="table", unique_key=["date", "id_deal", "has_id_check"]) }}
|
||||
{{
|
||||
config(
|
||||
materialized="table",
|
||||
unique_key=["date", "id_deal", "dash_source", "has_id_check"],
|
||||
)
|
||||
}}
|
||||
|
||||
select
|
||||
-- Unique Key --
|
||||
icvp.payment_paid_date_utc as date,
|
||||
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when icbs.id_booking is not null then 'New Dash' else 'Old Dash'
|
||||
end as dash_source,
|
||||
case
|
||||
when icv.id_verification is null then 'W/O Id Check' else 'With Id Check'
|
||||
end as has_id_check,
|
||||
|
|
@ -75,5 +83,10 @@ left join
|
|||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||
on icuh.id_deal = icmas.id_deal
|
||||
and icvp.payment_paid_date_utc = icmas.date
|
||||
left join
|
||||
{{ ref("int_core__booking_summary") }} as icbs
|
||||
on icvp.id_verification_request = icbs.id_verification_request
|
||||
and icbs.is_user_in_new_dash = true
|
||||
and icbs.is_missing_id_deal = false
|
||||
where upper(icvp.payment_status) = {{ var("paid_payment_state") }}
|
||||
group by 1, 2, 3, 4, 5
|
||||
group by 1, 2, 3, 4, 5, 6
|
||||
|
|
|
|||
|
|
@ -1,8 +1,11 @@
|
|||
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
||||
{{ config(materialized="table", unique_key=["date", "id_deal", "dash_source"]) }}
|
||||
select
|
||||
-- Unique Key --
|
||||
icvr.verification_estimated_started_date_utc as date,
|
||||
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when icbs.id_booking is not null then 'New Dash' else 'Old Dash'
|
||||
end as dash_source,
|
||||
-- Dimensions --
|
||||
coalesce(
|
||||
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||
|
|
@ -20,5 +23,10 @@ left join
|
|||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||
on icuh.id_deal = icmas.id_deal
|
||||
and icvr.verification_estimated_started_date_utc = icmas.date
|
||||
left join
|
||||
{{ ref("int_core__booking_summary") }} as icbs
|
||||
on icvr.id_verification_request = icbs.id_verification_request
|
||||
and icbs.is_user_in_new_dash = true
|
||||
and icbs.is_missing_id_deal = false
|
||||
where icvr.verification_estimated_started_date_utc is not null
|
||||
group by 1, 2, 3, 4
|
||||
group by 1, 2, 3, 4, 5
|
||||
|
|
|
|||
|
|
@ -967,13 +967,15 @@ models:
|
|||
The unique key corresponds to the deepest granularity of the model,
|
||||
in this case:
|
||||
- date,
|
||||
- id_deal.
|
||||
- id_deal,
|
||||
- dash_source
|
||||
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- id_deal
|
||||
- dash_source
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
|
|
@ -988,6 +990,16 @@ models:
|
|||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: dash_source
|
||||
data_type: string
|
||||
description: Dashboard source, either old or new.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "New Dash"
|
||||
- "Old Dash"
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: string
|
||||
description: |
|
||||
|
|
@ -1271,13 +1283,15 @@ models:
|
|||
The unique key corresponds to the deepest granularity of the model,
|
||||
in this case:
|
||||
- date,
|
||||
- id_deal.
|
||||
- id_deal,
|
||||
- dash_source
|
||||
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- id_deal
|
||||
- dash_source
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
|
|
@ -1292,6 +1306,16 @@ models:
|
|||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: dash_source
|
||||
data_type: string
|
||||
description: Dashboard source, either old or new.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "New Dash"
|
||||
- "Old Dash"
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: string
|
||||
description: |
|
||||
|
|
@ -1575,13 +1599,15 @@ models:
|
|||
The unique key corresponds to the deepest granularity of the model,
|
||||
in this case:
|
||||
- date,
|
||||
- id_deal.
|
||||
- id_deal,
|
||||
- dash_source.
|
||||
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- id_deal
|
||||
- dash_source
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
|
|
@ -1596,6 +1622,16 @@ models:
|
|||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: dash_source
|
||||
data_type: string
|
||||
description: Dashboard source, either old or new.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "New Dash"
|
||||
- "Old Dash"
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: string
|
||||
description: |
|
||||
|
|
@ -1879,13 +1915,15 @@ models:
|
|||
The unique key corresponds to the deepest granularity of the model,
|
||||
in this case:
|
||||
- date,
|
||||
- id_deal.
|
||||
- id_deal,
|
||||
- dash_source
|
||||
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- id_deal
|
||||
- dash_source
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
|
|
@ -1900,6 +1938,16 @@ models:
|
|||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: dash_source
|
||||
data_type: string
|
||||
description: Dashboard source, either old or new.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "New Dash"
|
||||
- "Old Dash"
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: string
|
||||
description: |
|
||||
|
|
@ -2184,7 +2232,8 @@ models:
|
|||
in this case:
|
||||
- date,
|
||||
- id_deal,
|
||||
- has_id_check.
|
||||
- has_id_check,
|
||||
- dash_source
|
||||
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
|
|
@ -2192,6 +2241,7 @@ models:
|
|||
- date
|
||||
- id_deal
|
||||
- has_id_check
|
||||
- dash_source
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
|
|
@ -2206,6 +2256,16 @@ models:
|
|||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: dash_source
|
||||
data_type: string
|
||||
description: Dashboard source, either old or new.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "New Dash"
|
||||
- "Old Dash"
|
||||
|
||||
- name: has_id_check
|
||||
data_type: string
|
||||
description: Does the verification in the guest journey
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue