Merged PR 3394: Guest KPIs daily metrics models

# Description

Created new models for the new Guest KPIs
These are for created, started and completed guest journeys and the highest granularity.
These includes date (day), id_deal, has_payment, has_check_in (government id), accommodation segmentation and billing country

# 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.
- [ ] I have checked for DRY opportunities with other models and docs.
- [ ] 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: #23387
This commit is contained in:
Joaquin Ossa 2024-10-31 16:45:58 +00:00
commit 231411ce93
2 changed files with 193 additions and 0 deletions

View file

@ -0,0 +1,91 @@
{% set id_check = "GovernmentId" %}
{{
config(
materialized="table",
unique_key=["date", "id_deal", "has_payment", "has_id_check"],
)
}}
select
-- Unique Key --
b.check_in_date_utc as date,
coalesce(icuh.id_deal, 'UNSET') as id_deal,
case
when vp.id_verification_to_payment is null then false else true
end as has_payment,
case when v.id_verification is null then false else true end as has_id_check,
-- Dimensions --
coalesce(
icd.main_billing_country_iso_3_per_deal, 'UNSET'
) as main_billing_country_iso_3_per_deal,
coalesce(
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
) as active_accommodations_per_deal_segmentation,
-- Metrics --
count(
distinct case
when
vr.created_date_utc is not null
and upper(b.booking_state) <> {{ var("cancelled_booking_state") }}
then vr.id_verification_request
else null
end
) as created_guest_journeys_not_cancelled,
count(
distinct case
when
vr.verification_estimated_started_date_utc is not null
and upper(b.booking_state) <> {{ var("cancelled_booking_state") }}
then vr.id_verification_request
else null
end
) as started_guest_journeys_not_cancelled,
count(
distinct case
when
vr.verification_estimated_completed_date_utc is not null
and upper(b.booking_state) <> {{ var("cancelled_booking_state") }}
then vr.id_verification_request
else null
end
) as completed_guest_journeys_not_cancelled,
count(
distinct case
when vr.created_date_utc is not null
then vr.id_verification_request
else null
end
) as created_guest_journeys,
count(
distinct case
when vr.verification_estimated_started_date_utc is not null
then vr.id_verification_request
else null
end
) as started_guest_journeys,
count(
distinct case
when vr.verification_estimated_completed_date_utc is not null
then vr.id_verification_request
else null
end
) as completed_guest_journeys
from {{ ref("int_core__verification_requests") }} as vr
inner join
{{ ref("int_core__bookings") }} as b
on b.id_verification_request = vr.id_verification_request
left join
{{ ref("int_core__user_host") }} as icuh on vr.id_user_host = icuh.id_user_host
left join {{ ref("int_core__deal") }} as icd on icuh.id_deal = icd.id_deal
left join
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
on icuh.id_deal = icmas.id_deal
and b.check_in_date_utc = icmas.date
left join
{{ ref("int_core__verification_payments") }} as vp
on vp.id_verification_request = vr.id_verification_request
left join
{{ ref("stg_core__verification") }} as v
on v.id_verification_request = vr.id_verification_request
and v.verification = '{{ id_check }}'
group by 1, 2, 3, 4, 5, 6

View file

@ -3075,3 +3075,105 @@ models:
- name: cancelled_bookings
data_type: bigint
description: The month-to-date cancelled bookings for a given date, dimension and value.
- name: int_kpis__metric_daily_check_in_attributed_guest_journeys
description: |
This model computes Guest Journey metrics at the deepest granularity
level for the Guest Products KPIs.
This model uses the Check-In date of the bookings for the date attribute.
The unique key corresponds to the deepest granularity of the model,
in this case:
- date,
- id_deal,
- has_payment,
- has_id_check.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- id_deal
- has_payment
- has_id_check
columns:
- name: date
data_type: date
description: Date of Check-In of the bookings for the guest journeys.
tests:
- not_null
- name: id_deal
data_type: string
description: Unique identifier of an account.
tests:
- not_null
- name: has_payment
data_type: boolean
description: True if there has been any guest payments on the guest journey.
- name: has_id_check
data_type: boolean
description: True if there verification in the guest journey
includes Government Id Check for the bookings.
- name: active_accommodations_per_deal_segmentation
data_type: string
description: |
Segment value based on the number of listings booked in 12 months
for a given deal and date.
tests:
- not_null
- accepted_values:
values:
- "0"
- "01-05"
- "06-20"
- "21-60"
- "61+"
- "UNSET"
- name: main_billing_country_iso_3_per_deal
data_type: string
description: |
Main billing country of the host aggregated at Deal level.
tests:
- not_null
- name: created_guest_journeys_not_cancelled
data_type: bigint
description: |
Count of daily guest journeys created, excluding cancelled bookings,
in a given date and per specified dimension.
- name: started_guest_journeys_not_cancelled
data_type: bigint
description: |
Count of daily guest journeys started, excluding cancelled bookings,
in a given date and per specified dimension.
- name: completed_guest_journeys_not_cancelled
data_type: bigint
description: |
Count of daily guest journeys completed, excluding cancelled bookings,
in a given date and per specified dimension.
- name: created_guest_journeys
data_type: bigint
description: |
Count of daily guest journeys created in a given date and
per specified dimension.
- name: started_guest_journeys
data_type: bigint
description: |
Count of daily guest journeys started in a given date and
per specified dimension.
- name: completed_guest_journeys
data_type: bigint
description: |
Count of daily guest journeys completed in a given date and
per specified dimension.