data-dwh-dbt-project/models/intermediate/cross/int_booking_summary.sql

280 lines
11 KiB
MySQL
Raw Normal View History

{% set risk_booking_status = ("NOTAPPROVED", "FLAGGED") %}
{% set no_risk_booking_status = ("APPROVED", "NOFLAGS") %}
{% set incident_duplicated_status = "CLOSED - DUPLICATE" %}
{% set incident_finished_status = (
"RESOLVED",
"RESOLVED EXCEPTION",
"CLOSED - NO REPLY",
"CLOSED - OTHER",
"CLOSED - WAIVER CR",
"CLOSED - LATE REPORT",
"CLOSED - NOT COVERED",
"CLOSED - NOT LIABLE",
"CLOSED HOST REQUEST",
"CLOSED - NOT APPROVED",
"CLOSED - THIRD PARTY",
) %}
{% set days_from_checkout_to_completion = 14 %}
{{ 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") }}
),
int_resolutions__incidents as (
select * from {{ ref("int_resolutions__incidents") }}
),
-- This CTE handles the core backend booking information and aggregates service
-- details.
core_backend_booking_modelling as (
select
bts.id_booking,
bts.id_verification_request,
bts.id_accommodation,
bts.id_user_product_bundle,
bts.id_deal,
bts.id_user_host,
bts.id_user_guest,
bts.booking_status,
bts.program_name,
bts.booking_created_at_utc,
bts.booking_created_date_utc,
bts.booking_updated_at_utc,
bts.booking_updated_date_utc,
bts.booking_check_in_at_utc,
bts.booking_check_in_date_utc,
bts.booking_check_out_at_utc,
bts.booking_check_out_date_utc,
bts.booking_check_out_date_utc
+ {{ days_from_checkout_to_completion }} as booking_completed_date_utc,
bts.booking_number_of_nights,
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_first_chargeable_date_utc
) as service_first_chargeable_date_utc,
max(
bsd.service_last_chargeable_date_utc
) as service_last_chargeable_date_utc,
min(bsd.service_first_billable_date_utc) as service_first_billable_date_utc,
max(bsd.service_last_billable_date_utc) as service_last_billable_date_utc,
min(bsd.service_detail_created_at_utc) as service_first_created_at_utc,
max(bsd.service_detail_created_at_utc) as service_last_created_at_utc,
max(bsd.service_detail_updated_at_utc) as service_last_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
2025-04-08 12:09:08 +02:00
end
) as number_of_applied_upgraded_services,
count(
distinct case
when bsd.is_billable_service
then bsd.id_booking_service_detail
else null
end
) as number_of_applied_billable_services,
case
when
sum(bsd.service_total_price_in_gbp) > 0
and min(bsd.service_first_chargeable_date_utc) is not null
then true
else false
end as is_booking_chargeable,
case
when
sum(
case
when bsd.is_billable_service
then bsd.service_total_price_in_gbp
else 0
end
)
> 0
and min(bsd.service_first_billable_date_utc) is not null
then true
else false
end as is_booking_billable,
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 bts.id_verification_request is null then false else true
end as has_verification_request,
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.is_billable_service then 1 else 0 end) > 0
then true
else false
end as has_billable_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 = 'SCREENING'
and bsd.service_name <> {{ var("default_service") }}
then 1
else 0
end
)
> 0
then true
else false
end as has_upgraded_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,
bts.is_missing_id_deal,
case
when bts.host_currency_code is null then true else false
end as is_missing_host_currency_code,
case
when
(current_date - booking_check_out_date_utc)
> {{ days_from_checkout_to_completion }}
then true
else false
end as is_booking_past_completion_date,
case
when upper(bts.booking_status) in {{ risk_booking_status }}
then true
when upper(bts.booking_status) in {{ no_risk_booking_status }}
then false
else null
end as is_booking_flagged_as_risk
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_accommodation,
bts.id_user_product_bundle,
bts.id_deal,
bts.id_user_host,
bts.id_user_guest,
bts.booking_status,
bts.program_name,
bts.booking_created_at_utc,
bts.booking_created_date_utc,
bts.booking_updated_at_utc,
bts.booking_updated_date_utc,
bts.booking_check_in_at_utc,
bts.booking_check_in_date_utc,
bts.booking_check_out_at_utc,
bts.booking_check_out_date_utc,
bts.booking_number_of_nights,
bts.host_currency_code,
bts.is_missing_id_deal,
bts.is_user_in_new_dash,
bts.new_dash_version,
bts.user_in_new_dash_since_timestamp_at_utc
),
-- This CTE deduplicates resolution incidents by booking ID and aggregates payout
-- amounts.
deduplicated_incidents as (
select
id_booking,
sum(submitted_payout_amount_in_gbp) as submitted_payout_amount_in_gbp,
case
when sum(submitted_payout_amount_in_gbp) > 0 then true else false
end as has_submitted_payout,
case
when
sum(
case
when
upper(current_status_name)
in {{ incident_finished_status }}
then 1
else 0
end
)
> 0
then true
else false
end as is_incident_finished
from int_resolutions__incidents
where upper(current_status_name) != '{{ incident_duplicated_status }}'
group by 1
)
-- This CTE combines the core backend booking information with the deduplicated
-- incidents to provide a comprehensive booking summary.
select
-- Retrieve all previous backend booking modelling fields.
cbbm.*,
-- Retrieve incident resolution fields.
case
when di.id_booking is not null then true else false
end as has_resolution_incident,
coalesce(di.is_incident_finished, false) as has_resolution_incident_finished,
coalesce(di.has_submitted_payout, false) as has_resolution_submitted_payout,
submitted_payout_amount_in_gbp as resolution_submitted_payout_amount_in_gbp
from core_backend_booking_modelling cbbm
left join deduplicated_incidents di on cbbm.id_booking = di.id_booking