diff --git a/models/intermediate/resolutions/int_resolutions__incidents.sql b/models/intermediate/resolutions/int_resolutions__incidents.sql index e6d5c62..240953a 100644 --- a/models/intermediate/resolutions/int_resolutions__incidents.sql +++ b/models/intermediate/resolutions/int_resolutions__incidents.sql @@ -4,44 +4,52 @@ with ), logs_timeline as ( select - i.id_incident, + id_incident, ( select (comment ->> 'CreatedDate')::timestamp - from jsonb_array_elements(i.comment_logs::jsonb) comment + from jsonb_array_elements(comment_logs::jsonb) comment order by (comment ->> 'CreatedDate')::timestamp limit 1 - ) as first_comment_date, + ) as first_comment_at_utc, ( select (comment ->> 'CreatedDate')::timestamp - from jsonb_array_elements(i.comment_logs::jsonb) comment + from jsonb_array_elements(comment_logs::jsonb) comment order by (comment ->> 'CreatedDate')::timestamp desc limit 1 - ) as last_comment_date, + ) as last_comment_at_utc, ( - select count(*) from jsonb_array_elements(i.comment_logs::jsonb) comment + select count(*) from jsonb_array_elements(comment_logs::jsonb) comment ) as comment_count, ( - select count(*) - from jsonb_array_elements(i.damage_report_items::jsonb) items - ) as number_damaged_items, - - from stg_resolutions__incidents i + 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 - i.id_incident, - jsonb_array_elements(i.documents -> 'DamageReport' -> 'Items') as item - from stg_resolutions__incidents i - ) - damage_report_amounts 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, - sum((corrective_measures ->> 'Amount')::numeric) as asked_repair_amount, + count(distinct item ->> 'Id') as number_damaged_items, -- Counting unique damaged items sum( - (corrective_measures ->> 'SettlementAmount')::numeric - ) as accepted_amount, + coalesce((corrective_measures ->> 'Amount')::numeric, 0) + ) as asked_repair_amount, + sum( + coalesce((corrective_measures ->> 'SettlementAmount')::numeric, 0) + ) as accepted_amount from - parsed_data, + damage_reported_items, jsonb_array_elements(item -> 'CorrectiveMeasures') as corrective_measures group by id_incident ) @@ -64,8 +72,23 @@ select updated_date_date, -- Resolution Details - first_comment_date, - last_comment_date, + 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, @@ -147,4 +170,5 @@ select calculated_guest_charge_amount_in_usd from stg_resolutions__incidents i -left join comments_timeline ct on i.id_incident = ct.id_incident +left join logs_timeline lt on i.id_incident = lt.id_incident +left join damage_report dr on i.id_incident = dr.id_incident