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

174 lines
5.1 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
),
damage_report as (
select
id_incident,
count(distinct item ->> 'Id') as number_damaged_items, -- Counting unique damaged items
sum(
coalesce((corrective_measures ->> 'Amount')::numeric, 0)
) as asked_repair_amount,
sum(
coalesce((corrective_measures ->> 'SettlementAmount')::numeric, 0)
) as accepted_amount
from
damage_reported_items,
jsonb_array_elements(item -> 'CorrectiveMeasures') as corrective_measures
group by id_incident
)
select
-- Basic Incident Details
i.id_incident,
id_user,
id_verification,
current_status_name,
is_submission_complete,
current_agent_name,
read_only_for_customers,
status_history_logs,
document_version,
task_execution_logs,
created_at_date,
created_date_date,
updated_at_date,
updated_date_date,
-- 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 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.asked_repair_amount,
dr.accepted_amount,
-- Host Details
id_user_host,
host_user_claim_logs,
host_account_name,
-- Host Contact Details
host_email,
host_last_name,
host_first_name,
host_phone_code,
host_phone_number,
host_phone_number_with_code,
-- Guest Details
id_user_guest,
guest_email,
guest_last_name,
guest_first_name,
guest_phone_code,
guest_phone_number,
guest_phone_number_with_code,
-- Guest Deposit Details
is_guest_deposit_retained,
is_guest_deposit_collected,
deposit_retained_amount_in_txn_currency,
deposit_retained_currency,
-- Guest Involvements
has_guest_contributed_to_cost,
has_host_taken_preventative_steps,
guest_contribution_amount_in_txn_currency,
guest_contribution_currency,
guest_contacted_about_damage,
guest_contacted_evidence_files,
guest_preventative_steps_details,
-- Accommodation Details
id_accommodation,
accommodation_url,
accommodation_name,
are_pets_allowed,
-- Booking Details
check_in_at_utc,
check_in_date_utc,
check_out_at_utc,
check_out_date_utc,
id_booking,
booking_status,
id_reservation,
booking_details,
number_of_guests,
booking_services,
booking_protection,
booking_platform_used,
booking_platform_reference,
-- Damage Report
before_damage_evidence,
original_invoice_evidence,
damage_incident_details,
has_confirmed_loss,
damage_report_items,
-- Calculator
protection_name,
was_overriden,
waiver_or_deposit_name,
guest_verification_status,
lower_protection_limit_usd,
upper_protection_limit_usd,
calculated_payout_amount_in_txn_currency,
calculated_payout_currency,
calculated_payout_amount_in_usd,
calculated_guest_charge_amount_in_txn_currency,
calculated_guest_charge_currency,
calculated_guest_charge_amount_in_usd
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