Update it to 1 model and added metrics including cancelled bookings
This commit is contained in:
parent
36a1428b23
commit
813e710020
4 changed files with 92 additions and 135 deletions
|
|
@ -0,0 +1,92 @@
|
|||
{% 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 }}'
|
||||
where b.check_in_date_utc is not null
|
||||
group by 1, 2, 3, 4, 5, 6
|
||||
|
|
@ -1,45 +0,0 @@
|
|||
{% set id_check = "GovernmentId" %}
|
||||
{% set cancelled_bookings = "Cancelled" %}
|
||||
|
||||
{{ 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 vr.id_verification_request) 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
|
||||
and b.booking_state <> '{{ cancelled_bookings }}'
|
||||
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 }}'
|
||||
where b.check_in_date_utc is not null
|
||||
and vr.verification_estimated_completed_date_utc is not null
|
||||
group by 1, 2, 3, 4, 5, 6
|
||||
|
|
@ -1,45 +0,0 @@
|
|||
{% set id_check = "GovernmentId" %}
|
||||
{% set cancelled_bookings = "Cancelled" %}
|
||||
|
||||
{{ 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 vr.id_verification_request) as created_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
|
||||
and b.booking_state <> '{{ cancelled_bookings }}'
|
||||
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 }}'
|
||||
where b.check_in_date_utc is not null
|
||||
and vr.created_date_utc is not null
|
||||
group by 1, 2, 3, 4, 5, 6
|
||||
|
|
@ -1,45 +0,0 @@
|
|||
{% set id_check = "GovernmentId" %}
|
||||
{% set cancelled_bookings = "Cancelled" %}
|
||||
|
||||
{{ 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 vr.id_verification_request) as started_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
|
||||
and b.booking_state <> '{{ cancelled_bookings }}'
|
||||
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 }}'
|
||||
where b.check_in_date_utc is not null
|
||||
and vr.verification_estimated_started_date_utc is not null
|
||||
group by 1, 2, 3, 4, 5, 6
|
||||
Loading…
Add table
Add a link
Reference in a new issue