Final changes

This commit is contained in:
Joaquin Ossa 2025-02-25 09:13:41 +01:00
parent daa93c056c
commit c49239a7cf
2 changed files with 54 additions and 13 deletions

View file

@ -2,6 +2,7 @@ with
stg_resolutions__incidents as (
select * from {{ ref("stg_resolutions__incidents") }}
),
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
int_daily_currency_exchange_rates as (
select * from {{ ref("int_daily_currency_exchange_rates") }}
),
@ -37,26 +38,50 @@ with
) as last_status_at_utc
from stg_resolutions__incidents
),
-- 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.
damage_reported_items as (
select id_incident, jsonb_array_elements(damage_report_items::jsonb) as item,
from stg_resolutions__incidents
where damage_report_items is not null
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
),
damage_report as (
select
dri.id_incident,
dri.host_currency,
count(distinct dri.item ->> 'Id') as number_damaged_items,
sum(
coalesce((cm.corrective_measure ->> 'OriginalAmount')::numeric, 0)
coalesce(
((dri.item ->> 'OriginalAmount')::numeric * cer.rate)::decimal(
19, 4
),
0
)
) as original_value_amount_in_txn_currency,
sum(
coalesce((cm.corrective_measure ->> 'Amount')::numeric, 0)
coalesce(
((cm.corrective_measure ->> 'Amount')::numeric * cer.rate)::decimal(
19, 4
),
0
)
) as asked_repair_amount_in_txn_currency,
sum(
coalesce((cm.corrective_measure ->> 'SettlementAmount')::numeric, 0)
coalesce(
(
(cm.corrective_measure ->> 'SettlementAmount')::numeric
* cer.rate
)::decimal(19, 4),
0
)
) as accepted_amount_in_txn_currency
from damage_reported_items dri
left join int_daily_currency_exchange_rates cer
left join
lateral jsonb_array_elements(
case
@ -66,7 +91,12 @@ with
end
) as cm(corrective_measure)
on true
group by dri.id_incident
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
group by dri.id_incident, dri.host_currency
)
select
@ -101,6 +131,7 @@ select
dr.original_value_amount_in_txn_currency,
dr.asked_repair_amount_in_txn_currency,
dr.accepted_amount_in_txn_currency,
dr.host_currency,
-- Resolutions calculator
i.protection_name,