data-dwh-dbt-project/models/intermediate/resolutions/int_resolutions__incidents.sql
2025-02-25 15:25:37 +01:00

162 lines
5.2 KiB
SQL

with
stg_resolutions__incidents as (
select * from {{ ref("stg_resolutions__incidents") }}
),
logs_timeline as (
select
id_incident,
(
select (comment ->> 'CreatedDate')::timestamp
from jsonb_array_elements(comment_logs::jsonb) comment
order by (comment ->> 'CreatedDate')::timestamp
limit 1
) as first_comment_at_utc,
(
select (comment ->> 'CreatedDate')::timestamp
from jsonb_array_elements(comment_logs::jsonb) comment
order by (comment ->> 'CreatedDate')::timestamp desc
limit 1
) as last_comment_at_utc,
(
select count(*) from jsonb_array_elements(comment_logs::jsonb) comment
) as comment_count,
(
select (status_step ->> 'CreatedDate')::timestamp
from jsonb_array_elements(status_history_logs::jsonb) status_step
order by (status_step ->> 'CreatedDate')::timestamp
limit 1
) as first_status_at_utc,
(
select (status_step ->> 'CreatedDate')::timestamp
from jsonb_array_elements(status_history_logs::jsonb) status_step
order by (status_step ->> 'CreatedDate')::timestamp desc
limit 1
) as last_status_at_utc
from stg_resolutions__incidents
),
damage_reported_items as (
select id_incident, jsonb_array_elements(damage_report_items::jsonb) as item -- No need for 'Items' if already an array
from stg_resolutions__incidents
where damage_report_items is not null
),
damage_report as (
select
dri.id_incident,
count(distinct dri.item ->> 'Id') as number_damaged_items,
sum(
coalesce((cm.corrective_measure ->> 'OriginalAmount')::numeric, 0)
) as original_value_amount_in_txn_currency,
sum(
coalesce((cm.corrective_measure ->> 'Amount')::numeric, 0)
) as asked_repair_amount_in_txn_currency,
sum(
coalesce((cm.corrective_measure ->> 'SettlementAmount')::numeric, 0)
) as accepted_amount_in_txn_currency
from damage_reported_items dri
left join
lateral jsonb_array_elements(
case
when jsonb_typeof(dri.item -> 'CorrectiveMeasures') = 'array'
then dri.item -> 'CorrectiveMeasures'
else '[]'::jsonb
end
) as cm(corrective_measure)
on true
group by dri.id_incident
)
select
-- Basic Incident Details
i.id_incident,
i.id_verification,
i.current_status_name,
i.is_submission_complete,
i.current_agent_name,
i.document_version,
i.created_at_utc,
i.created_date_utc,
i.updated_at_utc,
i.updated_date_utc,
-- Resolution Details
lt.first_comment_at_utc,
lt.last_comment_at_utc,
lt.comment_count,
lt.first_status_at_utc,
lt.last_status_at_utc,
case
when i.is_submission_complete
then
(
extract(epoch from (lt.last_status_at_utc - lt.first_status_at_utc))
/ 3600
)::decimal(19, 4)
else null
end as resolution_time_in_hours,
dr.number_damaged_items,
dr.original_value_amount_in_txn_currency,
dr.asked_repair_amount_in_txn_currency,
dr.accepted_amount_in_txn_currency,
-- Resolutions calculator
i.protection_name,
i.was_overriden,
i.waiver_or_deposit_name,
i.guest_verification_status,
i.lower_protection_limit_usd,
i.upper_protection_limit_usd,
i.calculated_payout_amount_in_txn_currency,
i.calculated_payout_currency,
i.calculated_payout_amount_in_usd,
i.calculated_guest_charge_amount_in_txn_currency,
i.calculated_guest_charge_currency,
i.calculated_guest_charge_amount_in_usd,
-- Host Details
i.id_user_host,
i.host_account_name,
-- Host Contact Details
i.host_email,
i.host_last_name,
i.host_first_name,
i.host_phone_code,
i.host_phone_number,
-- Guest Details
i.id_user_guest,
i.guest_email,
i.guest_last_name,
i.guest_first_name,
i.guest_phone_code,
i.guest_phone_number,
-- Guest Deposit Details
i.is_guest_deposit_retained,
i.is_guest_deposit_collected,
i.deposit_retained_amount_in_txn_currency,
i.deposit_retained_currency,
-- Guest Involvements
i.has_guest_contributed_to_cost,
i.has_host_taken_preventative_steps,
i.guest_contribution_amount_in_txn_currency,
i.guest_contribution_currency,
i.is_guest_contacted_about_damage,
-- Accommodation Details
i.id_accommodation,
i.accommodation_name,
-- Booking Details
i.check_in_at_utc,
i.check_in_date_utc,
i.check_out_at_utc,
i.check_out_date_utc,
i.id_booking,
i.booking_status,
i.id_reservation
from stg_resolutions__incidents i
left join logs_timeline lt on i.id_incident = lt.id_incident
left join damage_report dr on i.id_incident = dr.id_incident