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, ( select count(*) from jsonb_array_elements(host_user_claim_logs::jsonb) comment ) as claims_count 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, id_user, id_verification, current_status_name, is_submission_complete, current_agent_name, document_version, created_at_utc, created_date_utc, updated_at_utc, 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 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 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 -- Host Details id_user_host, lt.claims_count, host_account_name, -- Host Contact Details host_email, host_last_name, host_first_name, host_phone_code, host_phone_number, -- Guest Details id_user_guest, guest_email, guest_last_name, guest_first_name, guest_phone_code, guest_phone_number, -- 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, -- Accommodation Details id_accommodation, accommodation_name, -- 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_protection 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