data-dwh-dbt-project/models/intermediate/resolutions/int_resolutions__incidents.sql

272 lines
9.2 KiB
MySQL
Raw Normal View History

2025-02-21 16:26:07 +01:00
with
stg_resolutions__incidents as (
select * from {{ ref("stg_resolutions__incidents") }}
2025-02-21 18:11:53 +01:00
),
2025-02-25 09:13:41 +01:00
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
2025-02-24 16:50:18 +01:00
int_daily_currency_exchange_rates as (
select * from {{ ref("int_daily_currency_exchange_rates") }}
),
2025-02-21 19:16:28 +01:00
logs_timeline as (
2025-02-21 18:11:53 +01:00
select
2025-02-21 19:59:30 +01:00
id_incident,
2025-02-21 18:11:53 +01:00
(
select (comment ->> 'CreatedDate')::timestamp
2025-02-21 19:59:30 +01:00
from jsonb_array_elements(comment_logs::jsonb) comment
2025-02-21 18:11:53 +01:00
order by (comment ->> 'CreatedDate')::timestamp
limit 1
2025-02-21 19:59:30 +01:00
) as first_comment_at_utc,
2025-02-21 18:11:53 +01:00
(
select (comment ->> 'CreatedDate')::timestamp
2025-02-21 19:59:30 +01:00
from jsonb_array_elements(comment_logs::jsonb) comment
2025-02-21 18:11:53 +01:00
order by (comment ->> 'CreatedDate')::timestamp desc
limit 1
2025-02-21 19:59:30 +01:00
) as last_comment_at_utc,
2025-02-21 19:16:28 +01:00
(
2025-02-21 19:59:30 +01:00
select count(*) from jsonb_array_elements(comment_logs::jsonb) comment
2025-02-21 19:16:28 +01:00
) as comment_count,
(
2025-02-21 19:59:30 +01:00
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
2025-02-24 14:53:24 +01:00
) as last_status_at_utc
2025-02-21 19:59:30 +01:00
from stg_resolutions__incidents
2025-02-21 19:16:28 +01:00
),
2025-02-25 09:13:41 +01:00
-- The host can submit any number of damaged items in the damage report.
-- Each damaged item can have different currencies, so we need to convert
-- the amount to the host's currency.
2025-02-21 19:16:28 +01:00
damage_reported_items as (
2025-02-25 09:13:41 +01:00
select
i.id_incident,
jsonb_array_elements(i.damage_report_items::jsonb) as item,
uh.account_currency_iso4217 as host_currency,
i.created_date_utc
from stg_resolutions__incidents i
left join int_core__user_host uh on i.id_user_host = uh.id_user_host
where i.damage_report_items is not null
2025-02-21 19:59:30 +01:00
),
damage_report as (
2025-02-21 19:16:28 +01:00
select
2025-02-23 14:50:51 +01:00
dri.id_incident,
2025-02-25 09:13:41 +01:00
dri.host_currency,
2025-02-23 14:50:51 +01:00
count(distinct dri.item ->> 'Id') as number_damaged_items,
2025-02-22 12:42:20 +01:00
sum(
2025-02-25 09:13:41 +01:00
coalesce(
((dri.item ->> 'OriginalAmount')::numeric * cer.rate)::decimal(
19, 4
),
0
)
2025-02-25 16:58:14 +01:00
) as original_value_amount_in_host_currency,
sum(
coalesce(
((dri.item ->> 'OriginalAmount')::numeric * cer_gbp.rate)::decimal(
19, 4
),
0
)
) as original_value_amount_in_gbp,
2025-02-21 19:16:28 +01:00
sum(
2025-02-25 09:13:41 +01:00
coalesce(
((cm.corrective_measure ->> 'Amount')::numeric * cer.rate)::decimal(
19, 4
),
0
)
2025-02-25 16:58:14 +01:00
) as asked_repair_amount_in_host_currency,
sum(
coalesce(
(
(cm.corrective_measure ->> 'Amount')::numeric * cer_gbp.rate
)::decimal(19, 4),
0
)
) as asked_repair_amount_in_gbp,
2025-02-21 19:59:30 +01:00
sum(
2025-02-25 09:13:41 +01:00
coalesce(
(
(cm.corrective_measure ->> 'SettlementAmount')::numeric
* cer.rate
)::decimal(19, 4),
0
)
2025-02-25 16:58:14 +01:00
) as accepted_amount_in_host_currency,
sum(
coalesce(
(
(cm.corrective_measure ->> 'SettlementAmount')::numeric
* cer_gbp.rate
)::decimal(19, 4),
0
)
) as accepted_amount_in_gbp
2025-02-23 14:50:51 +01:00
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
2025-02-25 09:13:41 +01:00
left join
int_daily_currency_exchange_rates cer
on dri.created_date_utc = cer.rate_date_utc
and (cm.corrective_measure ->> 'Currency') = cer.from_currency
and dri.host_currency = cer.to_currency
2025-02-25 16:58:14 +01:00
left join
int_daily_currency_exchange_rates cer_gbp
on dri.created_date_utc = cer_gbp.rate_date_utc
and (cm.corrective_measure ->> 'Currency') = cer_gbp.from_currency
2025-02-26 16:22:32 +01:00
and cer_gbp.to_currency = 'GBP'
2025-02-25 09:13:41 +01:00
group by dri.id_incident, dri.host_currency
2025-02-25 16:58:14 +01:00
),
guest_amounts_in_gbp as (
select
i.id_incident,
2025-02-26 08:24:50 +01:00
(i.guest_contribution_amount_in_txn_currency * cer.rate)::decimal(
2025-02-25 16:58:14 +01:00
19, 4
2025-02-26 08:24:50 +01:00
) as guest_contribution_amount_in_gbp
2025-02-25 16:58:14 +01:00
from stg_resolutions__incidents i
left join
2025-02-26 08:24:50 +01:00
int_daily_currency_exchange_rates cer
on (i.calculation_at_utc)::date = cer.rate_date_utc
and cer.from_currency = i.guest_contribution_currency
and cer.to_currency = 'GBP'
2025-02-21 16:26:07 +01:00
)
2025-02-21 16:25:41 +01:00
select
-- Basic Incident Details
2025-02-21 18:11:53 +01:00
i.id_incident,
2025-02-23 16:59:43 +01:00
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,
2025-02-21 16:25:41 +01:00
2025-02-21 18:11:53 +01:00
-- Resolution Details
2025-02-21 19:59:30 +01:00
lt.first_comment_at_utc,
lt.last_comment_at_utc,
lt.comment_count,
case
when lt.first_comment_at_utc is not null
then
(
extract(epoch from (lt.first_comment_at_utc - i.created_at_utc)) / 3600
)::decimal(19, 4)
else null
end as time_to_first_comment_in_hours,
2025-02-21 19:59:30 +01:00
lt.first_status_at_utc,
lt.last_status_at_utc,
case
2025-02-23 16:59:43 +01:00
when i.is_submission_complete
2025-02-21 19:59:30 +01:00
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,
2025-02-25 16:58:14 +01:00
dr.original_value_amount_in_host_currency,
dr.original_value_amount_in_gbp,
dr.asked_repair_amount_in_host_currency,
dr.asked_repair_amount_in_gbp,
dr.accepted_amount_in_host_currency,
dr.accepted_amount_in_gbp,
2025-02-25 09:13:41 +01:00
dr.host_currency,
2025-02-22 12:42:20 +01:00
-- Resolutions calculator
2025-02-23 16:59:43 +01:00
i.protection_name,
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,
2025-02-25 16:58:14 +01:00
(i.calculated_payout_amount_in_usd * cer.rate)::decimal(
19, 4
) as calculated_payout_amount_in_gbp,
2025-02-28 12:19:24 +01:00
i.submitted_payout_amount_in_txn_currency,
i.submitted_payout_currency,
(i.submitted_payout_amount_in_usd * cer.rate)::decimal(
19, 4
) as submitted_payout_amount_in_gbp,
i.calculated_guest_charge_amount_in_txn_currency,
i.calculated_guest_charge_currency,
(i.calculated_guest_charge_amount_in_usd * cer.rate)::decimal(
19, 4
) as calculated_guest_charge_amount_in_gbp,
2025-02-26 16:45:01 +01:00
i.submitted_guest_charge_amount_in_txn_currency,
i.submitted_guest_charge_currency,
(i.submitted_guest_charge_amount_in_usd * cer.rate)::decimal(
2025-02-25 16:58:14 +01:00
19, 4
2025-02-26 16:45:01 +01:00
) as submitted_guest_charge_amount_in_gbp,
2025-02-21 18:11:53 +01:00
2025-02-21 16:25:41 +01:00
-- Host Details
2025-02-23 16:59:43 +01:00
i.id_user_host,
i.host_account_name,
2025-02-21 16:25:41 +01:00
-- Host Contact Details
2025-02-23 16:59:43 +01:00
i.host_email,
i.host_last_name,
i.host_first_name,
i.host_phone_code,
i.host_phone_number,
2025-02-21 16:25:41 +01:00
-- Guest Details
2025-02-23 16:59:43 +01:00
i.id_user_guest,
i.guest_email,
i.guest_last_name,
i.guest_first_name,
i.guest_phone_code,
i.guest_phone_number,
2025-02-21 16:25:41 +01:00
-- Guest Deposit Details
2025-02-23 16:59:43 +01:00
i.is_guest_deposit_retained,
i.is_guest_deposit_collected,
i.deposit_retained_amount_in_txn_currency,
i.deposit_retained_currency,
2025-02-21 16:25:41 +01:00
-- Guest Involvements
2025-02-23 16:59:43 +01:00
i.has_guest_contributed_to_cost,
i.has_host_taken_preventative_steps,
i.guest_contribution_amount_in_txn_currency,
i.guest_contribution_currency,
2025-02-25 16:58:14 +01:00
ga.guest_contribution_amount_in_gbp,
2025-02-24 14:53:24 +01:00
i.is_guest_contacted_about_damage,
2025-02-21 16:25:41 +01:00
-- Accommodation Details
2025-02-23 16:59:43 +01:00
i.id_accommodation,
i.accommodation_name,
2025-02-21 16:25:41 +01:00
-- Booking Details
2025-02-23 16:59:43 +01:00
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,
2025-02-24 14:53:24 +01:00
i.id_reservation
2025-02-21 18:11:53 +01:00
from stg_resolutions__incidents i
2025-02-21 19:59:30 +01:00
left join logs_timeline lt on i.id_incident = lt.id_incident
left join damage_report dr on i.id_incident = dr.id_incident
2025-02-25 16:58:14 +01:00
left join guest_amounts_in_gbp ga on i.id_incident = ga.id_incident
left join
int_daily_currency_exchange_rates cer
2025-02-26 08:24:50 +01:00
on (i.calculation_at_utc)::date = cer.rate_date_utc
2025-02-25 16:58:14 +01:00
and cer.from_currency = 'USD'
and cer.to_currency = 'GBP'