Addressed comments

This commit is contained in:
Joaquin Ossa 2025-02-25 16:58:14 +01:00
parent c49239a7cf
commit cfc6971cb4
2 changed files with 152 additions and 15 deletions

View file

@ -63,7 +63,15 @@ with
),
0
)
) as original_value_amount_in_txn_currency,
) 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,
sum(
coalesce(
((cm.corrective_measure ->> 'Amount')::numeric * cer.rate)::decimal(
@ -71,7 +79,15 @@ with
),
0
)
) as asked_repair_amount_in_txn_currency,
) 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,
sum(
coalesce(
(
@ -80,7 +96,16 @@ with
)::decimal(19, 4),
0
)
) as accepted_amount_in_txn_currency
) 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
from damage_reported_items dri
left join
lateral jsonb_array_elements(
@ -96,7 +121,34 @@ with
on dri.created_date_utc = cer.rate_date_utc
and (cm.corrective_measure ->> 'Currency') = cer.from_currency
and dri.host_currency = cer.to_currency
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
and 'GBP' = cer.to_currency
group by dri.id_incident, dri.host_currency
),
guest_amounts_in_gbp as (
select
i.id_incident,
(i.deposit_retained_amount_in_txn_currency * cer_deposit.rate)::decimal(
19, 4
) as deposit_retained_amount_in_gbp,
(
i.guest_contribution_amount_in_txn_currency * cer_contribution.rate
)::decimal(19, 4) as guest_contribution_amount_in_gbp
from stg_resolutions__incidents i
left join logs_timeline lt on i.id_incident = lt.id_incident
left join
int_daily_currency_exchange_rates cer_deposit
on (lt.last_status_at_utc)::date = cer_deposit.rate_date_utc
and cer_deposit.from_currency = i.deposit_retained_currency
and cer_deposit.to_currency = 'GBP'
left join
int_daily_currency_exchange_rates cer_contribution
on (lt.last_status_at_utc)::date = cer_contribution.rate_date_utc
and cer_contribution.from_currency = i.guest_contribution_currency
and cer_contribution.to_currency = 'GBP'
)
select
@ -128,9 +180,12 @@ select
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,
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,
dr.host_currency,
-- Resolutions calculator
@ -143,9 +198,15 @@ select
i.calculated_payout_amount_in_txn_currency,
i.calculated_payout_currency,
i.calculated_payout_amount_in_usd,
(i.calculated_payout_amount_in_usd * cer.rate)::decimal(
19, 4
) as calculated_payout_amount_in_gbp,
i.calculated_guest_charge_amount_in_txn_currency,
i.calculated_guest_charge_currency,
i.calculated_guest_charge_amount_in_usd,
(i.calculated_guest_charge_amount_in_usd * cer.rate)::decimal(
19, 4
) as calculated_guest_charge_amount_in_gbp,
-- Host Details
i.id_user_host,
@ -171,12 +232,14 @@ select
i.is_guest_deposit_collected,
i.deposit_retained_amount_in_txn_currency,
i.deposit_retained_currency,
ga.deposit_retained_amount_in_gbp,
-- Guest Involvements
i.has_guest_contributed_to_cost,
i.has_host_taken_preventative_steps,
i.guest_contribution_amount_in_txn_currency,
i.guest_contribution_currency,
ga.guest_contribution_amount_in_gbp,
i.is_guest_contacted_about_damage,
-- Accommodation Details
@ -195,3 +258,9 @@ select
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
left join guest_amounts_in_gbp ga on i.id_incident = ga.id_incident
left join
int_daily_currency_exchange_rates cer
on (lt.last_status_at_utc)::date = cer.rate_date_utc
and cer.from_currency = 'USD'
and cer.to_currency = 'GBP'