-
Notifications
You must be signed in to change notification settings - Fork 3
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
feat(reporting): dbt credit facility models (#1328)
* feat: credit facility modular event-sync tables * feat: credit facility higher level consistent view * feat: cradit facility cash flow projection * feat: credit facility per customer & c.f. cash flow * feat: credit facility per customer & c.f. tvm risk * feat: credit facility firm-wide cash flows * feat: credit facility firm-wide tvm risk * feat: kpi & int models for risk management dashbord
- Loading branch information
1 parent
3c7f905
commit 6118680
Showing
19 changed files
with
1,356 additions
and
2 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
35 changes: 35 additions & 0 deletions
35
...form/models/intermediate/credit_facilities/int_cf_agg_projected_cash_flows_timeseries.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,35 @@ | ||
with projected_cash_flows_common as ( | ||
select * | ||
from {{ ref('int_cf_projected_cash_flows_common') }} | ||
where credit_facility_end_date >= now_ts | ||
), | ||
|
||
grouped as ( | ||
select | ||
now_ts, | ||
days_per_year, | ||
bench_mark_daily_interest_rate, | ||
days_from_now, | ||
sum(projected_disbursal_amount_in_cents) | ||
as projected_disbursal_amount_in_cents, | ||
sum(projected_payment_amount_in_cents) | ||
as projected_payment_amount_in_cents | ||
from projected_cash_flows_common | ||
group by | ||
now_ts, | ||
days_per_year, | ||
bench_mark_daily_interest_rate, | ||
days_from_now | ||
order by days_from_now | ||
) | ||
|
||
select | ||
*, | ||
timestamp( | ||
timestamp_add(date(now_ts), interval cast(days_from_now as int64) day) | ||
) as date_from_now, | ||
safe_divide(projected_disbursal_amount_in_cents, 100.0) | ||
as projected_disbursal_amount_in_usd, | ||
safe_divide(projected_payment_amount_in_cents, 100.0) | ||
as projected_payment_amount_in_usd | ||
from grouped |
137 changes: 137 additions & 0 deletions
137
...nsform/models/intermediate/credit_facilities/int_cf_agg_projected_cash_flows_tvm_risk.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,137 @@ | ||
with projected_cash_flows_common as ( | ||
select * | ||
from {{ ref('int_cf_projected_cash_flows_common') }} | ||
where credit_facility_end_date >= now_ts | ||
), | ||
|
||
grouped as ( | ||
select | ||
now_ts, | ||
days_per_year, | ||
bench_mark_daily_interest_rate, | ||
days_from_now, | ||
sum(projected_disbursal_amount_in_cents) | ||
as projected_disbursal_amount_in_cents, | ||
case | ||
when days_from_now < 0 then 0 else | ||
sum(projected_payment_amount_in_cents) | ||
end as projected_payment_amount_in_cents | ||
from projected_cash_flows_common | ||
group by | ||
now_ts, | ||
days_per_year, | ||
bench_mark_daily_interest_rate, | ||
days_from_now | ||
order by days_from_now | ||
), | ||
|
||
arrayed as ( | ||
select | ||
now_ts, | ||
days_per_year, | ||
bench_mark_daily_interest_rate, | ||
array_agg(projected_disbursal_amount_in_cents) | ||
as projected_disbursal_amount_in_cents, | ||
array_agg(days_from_now) as days_from_now, | ||
array_agg(projected_payment_amount_in_cents) as cash_flows | ||
from grouped | ||
group by | ||
now_ts, | ||
days_per_year, | ||
bench_mark_daily_interest_rate | ||
), | ||
|
||
with_risk as ( | ||
select | ||
now_ts, | ||
days_per_year, | ||
bench_mark_daily_interest_rate, | ||
projected_disbursal_amount_in_cents, | ||
days_from_now, | ||
cash_flows, | ||
{{ target.schema }}.udf_loan_pv( | ||
bench_mark_daily_interest_rate, | ||
days_from_now, | ||
projected_disbursal_amount_in_cents | ||
) as disbursal_pv, | ||
{{ target.schema }}.udf_loan_pv( | ||
bench_mark_daily_interest_rate, days_from_now, cash_flows | ||
) as pv, | ||
safe_multiply( | ||
{{ target.schema }}.udf_loan_ytm( | ||
bench_mark_daily_interest_rate, days_from_now, cash_flows | ||
), | ||
365.0 | ||
) as ytm, | ||
{{ target.schema }}.udf_loan_mac_duration( | ||
bench_mark_daily_interest_rate, days_from_now, cash_flows | ||
) as mac_duration, | ||
safe_divide( | ||
{{ target.schema }}.udf_loan_mod_duration( | ||
bench_mark_daily_interest_rate, days_from_now, cash_flows | ||
), | ||
365.0 | ||
) as mod_duration, | ||
safe_divide( | ||
{{ target.schema }}.udf_loan_convexity( | ||
bench_mark_daily_interest_rate, days_from_now, cash_flows | ||
), | ||
365.0 * 365.0 | ||
) as convexity, | ||
{{ target.schema }}.udf_loan_pv_delta_on_interest_rate_delta_with_convex( | ||
bench_mark_daily_interest_rate, | ||
days_from_now, | ||
cash_flows, | ||
0.0001 / days_per_year | ||
) as dv01, | ||
{{ target.schema }}.udf_loan_pv( | ||
bench_mark_daily_interest_rate + (0.0001 / days_per_year), | ||
days_from_now, | ||
cash_flows | ||
) as pv_at_dv01 | ||
from arrayed | ||
), | ||
|
||
final as ( | ||
select | ||
now_ts, | ||
days_per_year, | ||
bench_mark_daily_interest_rate, | ||
projected_disbursal_amount_in_cents, | ||
days_from_now, | ||
cash_flows, | ||
safe_divide(disbursal_pv, 100.0) as disbursal_pv, | ||
safe_divide(pv, 100.0) as pv, | ||
safe_divide( | ||
safe_add( | ||
{{ target.schema }}.udf_loan_pv( | ||
bench_mark_daily_interest_rate, days_from_now, cash_flows | ||
), | ||
disbursal_pv | ||
), | ||
100.0 | ||
) as npv, | ||
ytm, | ||
safe_multiply( | ||
{{ target.schema }}.udf_loan_ytm_from_price( | ||
safe_negate(disbursal_pv), days_from_now, cash_flows | ||
), | ||
365.0 | ||
) as ytm_from_price, | ||
mac_duration, | ||
case | ||
when is_nan(mac_duration) | ||
then timestamp('1900-01-01') | ||
else | ||
timestamp( | ||
timestamp_add( | ||
date(now_ts), interval cast(mac_duration as int64) day | ||
) | ||
) | ||
end as mac_duration_date, | ||
safe_divide(dv01, 100.0) as dv01, | ||
safe_divide(pv_at_dv01, 100.0) as pv_at_dv01 | ||
from with_risk | ||
) | ||
|
||
select * from final |
93 changes: 93 additions & 0 deletions
93
meltano/transform/models/intermediate/credit_facilities/int_cf_collaterals.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,93 @@ | ||
with collateral_updated as ( | ||
|
||
select | ||
id as event_id, | ||
cast(format_date('%Y%m%d', recorded_at) as int64) | ||
as recorded_at_date_key, | ||
recorded_at, | ||
event_type, | ||
cast( | ||
format_date( | ||
'%Y%m%d', | ||
parse_timestamp( | ||
'%Y-%m-%dT%H:%M:%E*SZ', | ||
json_value(event, '$.recorded_in_ledger_at'), | ||
'UTC' | ||
) | ||
) as int64 | ||
) as recorded_in_ledger_at_date_key, | ||
cast(json_value(event, '$.audit_info.audit_entry_id') as integer) | ||
as audit_entry_id, | ||
cast(json_value(event, '$.abs_diff') as numeric) as abs_diff, | ||
cast(json_value(event, '$.total_collateral') as numeric) | ||
as total_collateral, | ||
parse_timestamp( | ||
'%Y-%m-%dT%H:%M:%E*SZ', | ||
json_value(event, '$.recorded_in_ledger_at'), | ||
'UTC' | ||
) as recorded_in_ledger_at, | ||
json_value(event, '$.action') as action | ||
from {{ ref('stg_credit_facility_events') }} as cfe | ||
where | ||
cfe.event_type = 'collateral_updated' | ||
and json_value(event, '$.tx_id') is not null | ||
|
||
), | ||
|
||
collateralization_changed as ( | ||
|
||
select | ||
id as event_id, | ||
cast(format_date('%Y%m%d', recorded_at) as int64) | ||
as recorded_at_date_key, | ||
recorded_at, | ||
cast( | ||
format_date( | ||
'%Y%m%d', | ||
parse_timestamp( | ||
'%Y-%m-%dT%H:%M:%E*SZ', | ||
json_value(event, '$.recorded_at'), | ||
'UTC' | ||
) | ||
) as int64 | ||
) as event_recorded_at_date_key, | ||
cast(json_value(event, '$.audit_info.audit_entry_id') as integer) | ||
as audit_entry_id, | ||
cast(json_value(event, '$.collateral') as numeric) as collateral, | ||
cast(json_value(event, '$.price') as numeric) as price, | ||
cast(json_value(event, '$.outstanding.disbursed') as numeric) | ||
as outstanding_disbursed, | ||
cast(json_value(event, '$.outstanding.interest') as numeric) | ||
as outstanding_interest, | ||
parse_timestamp( | ||
'%Y-%m-%dT%H:%M:%E*SZ', json_value(event, '$.recorded_at'), 'UTC' | ||
) as event_recorded_at, | ||
json_value(event, '$.state') as state | ||
from {{ ref('stg_credit_facility_events') }} as cfe | ||
where cfe.event_type = 'collateralization_changed' | ||
|
||
) | ||
|
||
|
||
select | ||
cu.* except (abs_diff, total_collateral), | ||
|
||
cc.event_recorded_at as collateralization_changed_event_recorded_at, | ||
state as collateralization_changed_state, | ||
cu.total_collateral, | ||
|
||
cc.price, | ||
coalesce(cc.event_recorded_at_date_key, 19000101) | ||
as collateralization_changed_event_recorded_at_date_key, | ||
|
||
case | ||
when lower(action) = 'add' then cu.abs_diff else | ||
safe_negate(cu.abs_diff) | ||
end as diff, | ||
coalesce(cc.collateral, 0) as collateral, | ||
coalesce(cc.outstanding_disbursed, 0) as outstanding_disbursed, | ||
coalesce(cc.outstanding_interest, 0) as outstanding_interest | ||
from collateral_updated as cu | ||
left join | ||
collateralization_changed as cc | ||
on cu.event_id = cc.event_id and cu.audit_entry_id = cc.audit_entry_id |
54 changes: 54 additions & 0 deletions
54
meltano/transform/models/intermediate/credit_facilities/int_cf_denormalized.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,54 @@ | ||
with credit_facilities as ( | ||
|
||
select * from {{ ref('int_credit_facilities') }} | ||
|
||
), | ||
|
||
int_cf_disbursals as ( | ||
|
||
select * from {{ ref('int_cf_disbursals') }} | ||
|
||
), | ||
|
||
int_cf_collaterals as ( | ||
|
||
select * from {{ ref('int_cf_collaterals') }} | ||
|
||
), | ||
|
||
int_cf_payments as ( | ||
|
||
select * from {{ ref('int_cf_payments') }} | ||
|
||
) | ||
|
||
select | ||
cfe.*, | ||
|
||
d.* except (event_id, recorded_at_date_key, recorded_at, event_type), | ||
c.* except (event_id, recorded_at_date_key, recorded_at, event_type), | ||
p.* except ( | ||
event_id, | ||
recorded_at_date_key, | ||
recorded_at, | ||
event_type, | ||
recorded_in_ledger_at_date_key, | ||
recorded_in_ledger_at | ||
), | ||
d.recorded_at_date_key as disbursal_recorded_at_date_key, | ||
|
||
d.recorded_at as disbursal_recorded_at, | ||
d.event_type as disbursal_event_type, | ||
c.recorded_at_date_key as collateral_recorded_at_date_key, | ||
c.recorded_at as collateral_recorded_at, | ||
|
||
c.event_type as collateral_event_type, | ||
p.recorded_at_date_key as payment_recorded_at_date_key, | ||
p.recorded_at as payment_recorded_at, | ||
p.event_type as payment_event_type, | ||
p.recorded_in_ledger_at_date_key as payment_recorded_in_ledger_at_date_key, | ||
p.recorded_in_ledger_at as payment_recorded_in_ledger_at | ||
from credit_facilities as cfe | ||
full join int_cf_disbursals as d on cfe.event_id = d.event_id | ||
full join int_cf_collaterals as c on cfe.event_id = c.event_id | ||
full join int_cf_payments as p on cfe.event_id = p.event_id |
Oops, something went wrong.