2025-04-15 10:14:02 +00:00
|
|
|
{{ config(materialized="table") }}
|
|
|
|
|
with
|
2025-05-30 12:51:10 +00:00
|
|
|
int_booking_summary as (select * from {{ ref("int_booking_summary") }}),
|
2025-04-15 10:14:02 +00:00
|
|
|
new_dash_protected_bookings as (
|
|
|
|
|
select
|
|
|
|
|
id_booking,
|
2025-06-02 15:56:54 +00:00
|
|
|
is_booking_past_completion_date as is_booking_completed,
|
|
|
|
|
is_booking_flagged_as_risk,
|
|
|
|
|
has_resolution_incident as has_claim,
|
|
|
|
|
has_resolution_submitted_payout as has_submitted_payout,
|
|
|
|
|
has_resolution_incident_finished as is_incident_finished,
|
|
|
|
|
coalesce(
|
|
|
|
|
resolution_submitted_payout_amount_in_gbp, 0
|
|
|
|
|
) as submitted_payout_amount_in_gbp
|
2025-05-30 12:51:10 +00:00
|
|
|
from int_booking_summary
|
2025-04-15 10:14:02 +00:00
|
|
|
where
|
|
|
|
|
-- Bookings from New Dash users with Id Deal
|
|
|
|
|
is_user_in_new_dash = true
|
|
|
|
|
and is_missing_id_deal = false
|
|
|
|
|
-- Protected Bookings with a Protection or a Deposit Management service
|
|
|
|
|
and (
|
|
|
|
|
has_protection_service_business_type
|
|
|
|
|
or has_deposit_management_service_business_type
|
|
|
|
|
)
|
2025-06-02 15:56:54 +00:00
|
|
|
-- Bookings with flagging categorisation (this excludes
|
|
|
|
|
-- Cancelled/Incomplete Information/Rejected bookings)
|
|
|
|
|
and is_booking_flagged_as_risk is not null
|
2025-04-15 10:14:02 +00:00
|
|
|
)
|
|
|
|
|
select
|
|
|
|
|
-- High Level Bookings --
|
|
|
|
|
count(id_booking) as total_bookings,
|
|
|
|
|
count(id_booking) filter (where is_booking_completed) as completed_bookings,
|
|
|
|
|
count(id_booking) filter (where not is_booking_completed) as not_completed_bookings,
|
|
|
|
|
|
|
|
|
|
-- High Level Claims --
|
|
|
|
|
count(id_booking) filter (where has_claim) as total_with_claim_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed with Claim --
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where is_booking_completed and has_claim
|
|
|
|
|
) as completed_with_claim_bookings,
|
|
|
|
|
-- Not Completed with Claim --
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where not is_booking_completed and has_claim
|
|
|
|
|
) as not_completed_with_claim_bookings,
|
|
|
|
|
-- Completed without Claim --
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where is_booking_completed and not has_claim
|
|
|
|
|
) as completed_without_claim_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed with Risk
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where is_booking_completed and is_booking_flagged_as_risk
|
|
|
|
|
) as completed_risk_bookings,
|
|
|
|
|
-- Completed without Risk
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where is_booking_completed and not is_booking_flagged_as_risk
|
|
|
|
|
) as completed_no_risk_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed awaiting resolution
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where is_booking_completed and has_claim and not is_incident_finished
|
|
|
|
|
) as completed_awaiting_resolution_bookings,
|
|
|
|
|
-- Completed not awaiting resolution
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and ((has_claim and is_incident_finished) or (not has_claim))
|
|
|
|
|
) as completed_not_awaiting_resolution_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed with Submitted Payout
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and has_submitted_payout
|
|
|
|
|
and is_incident_finished
|
|
|
|
|
and has_claim
|
|
|
|
|
) as completed_with_submitted_payout_bookings,
|
|
|
|
|
-- Completed without Submitted Payout
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and (
|
|
|
|
|
(has_claim and not has_submitted_payout and is_incident_finished)
|
|
|
|
|
or (not has_claim)
|
|
|
|
|
)
|
|
|
|
|
) as completed_without_submitted_payout_bookings,
|
|
|
|
|
|
|
|
|
|
-- CONFUSION MATRIX 1: RISK vs. CLAIM --
|
|
|
|
|
-- Completed with Risk and with Claim -- True Positives
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where is_booking_completed and is_booking_flagged_as_risk and has_claim
|
|
|
|
|
) as completed_risk_with_claim_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed without Risk and without Claim -- True Negatives
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where is_booking_completed and not is_booking_flagged_as_risk and not has_claim
|
|
|
|
|
) as completed_no_risk_without_claim_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed with Risk and without Claim -- False Positive
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where is_booking_completed and is_booking_flagged_as_risk and not has_claim
|
|
|
|
|
) as completed_risk_without_claim_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed without Risk and with Claim -- False Negatives
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where is_booking_completed and not is_booking_flagged_as_risk and has_claim
|
|
|
|
|
) as completed_no_risk_with_claim_bookings,
|
|
|
|
|
|
|
|
|
|
-- CONFUSION MATRIX 2: RISK vs. PAYOUT --
|
|
|
|
|
-- Completed with Risk, Incident is finished and with Submitted Payout --
|
|
|
|
|
-- True Positives
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and is_booking_flagged_as_risk
|
|
|
|
|
and has_claim
|
|
|
|
|
and has_submitted_payout
|
|
|
|
|
and is_incident_finished
|
|
|
|
|
) as completed_risk_with_submitted_payout_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed without Risk and without Submitted Payout -- True Negatives
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and not is_booking_flagged_as_risk
|
|
|
|
|
and (
|
|
|
|
|
(has_claim and not has_submitted_payout and is_incident_finished)
|
|
|
|
|
or (not has_claim)
|
|
|
|
|
)
|
|
|
|
|
) as completed_no_risk_without_submitted_payout_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed with Risk and without Submitted Payout -- False Positive
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and is_booking_flagged_as_risk
|
|
|
|
|
and (
|
|
|
|
|
(has_claim and not has_submitted_payout and is_incident_finished)
|
|
|
|
|
or (not has_claim)
|
|
|
|
|
)
|
|
|
|
|
) as completed_risk_without_submitted_payout_bookings,
|
|
|
|
|
|
|
|
|
|
-- Completed without Risk and with Submitted Payout -- False Negative
|
|
|
|
|
count(id_booking) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and not is_booking_flagged_as_risk
|
|
|
|
|
and has_submitted_payout
|
|
|
|
|
and has_claim
|
|
|
|
|
and is_incident_finished
|
2025-04-16 06:48:39 +00:00
|
|
|
) as completed_no_risk_with_submitted_payout_bookings,
|
|
|
|
|
|
|
|
|
|
-- ADDITIONAL PAYOUT INPUT - FOR CONFUSION MATRIX 2: RISK vs. PAYOUT --
|
|
|
|
|
-- Total amount paid for all bookings
|
|
|
|
|
sum(submitted_payout_amount_in_gbp) as total_amount_paid_in_gbp,
|
|
|
|
|
|
|
|
|
|
-- Amount paid from completed bookings
|
|
|
|
|
sum(submitted_payout_amount_in_gbp) filter (
|
|
|
|
|
where is_booking_completed
|
|
|
|
|
) as completed_amount_paid_in_gbp,
|
|
|
|
|
|
|
|
|
|
-- Amount paid from not completed bookings
|
|
|
|
|
sum(submitted_payout_amount_in_gbp) filter (
|
|
|
|
|
where not is_booking_completed
|
|
|
|
|
) as not_completed_amount_paid_in_gbp,
|
|
|
|
|
|
2025-04-17 08:15:37 +00:00
|
|
|
-- Amount paid from completed bookings with finished incidents
|
|
|
|
|
sum(submitted_payout_amount_in_gbp) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and has_claim
|
|
|
|
|
and is_incident_finished
|
|
|
|
|
and has_submitted_payout
|
|
|
|
|
) as completed_finished_incidents_amount_paid_in_gbp,
|
|
|
|
|
|
|
|
|
|
-- Amount paid from completed bookings with awaiting finish incidents
|
|
|
|
|
sum(submitted_payout_amount_in_gbp) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and has_claim
|
|
|
|
|
and not is_incident_finished
|
|
|
|
|
and has_submitted_payout
|
|
|
|
|
) as completed_awaiting_finish_incidents_amount_paid_in_gbp,
|
|
|
|
|
|
2025-04-16 06:48:39 +00:00
|
|
|
-- Completed with Risk, Incident is finished and with Submitted Payout --
|
|
|
|
|
-- True Positives - How much did we pay?
|
|
|
|
|
sum(submitted_payout_amount_in_gbp) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and is_booking_flagged_as_risk
|
|
|
|
|
and has_claim
|
|
|
|
|
and has_submitted_payout
|
|
|
|
|
and is_incident_finished
|
|
|
|
|
) as completed_risk_with_submitted_payout_amount_paid_in_gbp,
|
|
|
|
|
|
|
|
|
|
-- Completed without Risk and with Submitted Payout
|
|
|
|
|
-- False Negative - How much did we pay?
|
|
|
|
|
sum(submitted_payout_amount_in_gbp) filter (
|
|
|
|
|
where
|
|
|
|
|
is_booking_completed
|
|
|
|
|
and not is_booking_flagged_as_risk
|
|
|
|
|
and has_submitted_payout
|
|
|
|
|
and has_claim
|
|
|
|
|
and is_incident_finished
|
|
|
|
|
) as completed_no_risk_with_submitted_payout_amount_paid_in_gbp
|
|
|
|
|
|
2025-06-02 15:56:54 +00:00
|
|
|
from new_dash_protected_bookings
|