diff --git a/Makefile b/Makefile index a5fe4ccb3..5ec569454 100644 --- a/Makefile +++ b/Makefile @@ -114,3 +114,18 @@ tilt-in-ci: test-cypress-in-ci-through-browserstack: cd apps/admin-panel && pnpm cypress:run browserstack + +pg2bq-run: + meltano run tap-postgres target-bigquery + +bq-pipeline-run: + meltano run dbt-bigquery:run + +check-code-pipeline: + meltano invoke sqlfluff:lint + +lint-code-pipeline: + meltano invoke sqlfluff:fix + +bitfinex-run: + meltano run tap-bitfinexapi target-bigquery diff --git a/flake.nix b/flake.nix index a13e73251..16f151362 100644 --- a/flake.nix +++ b/flake.nix @@ -34,7 +34,7 @@ }; mkAlias = alias: command: pkgs.writeShellScriptBin alias command; aliases = [ - (mkAlias "meltano" ''docker compose run meltano -- "$@"'') + (mkAlias "meltano" ''docker compose run --rm meltano -- "$@"'') ]; nativeBuildInputs = with pkgs; [ diff --git a/meltano/.sqlfluff b/meltano/.sqlfluff index 53ede22ad..13175d8ec 100644 --- a/meltano/.sqlfluff +++ b/meltano/.sqlfluff @@ -3,7 +3,7 @@ templater = dbt dialect = bigquery exclude_rules = structure.using,references.qualification,references.from runaway_limit = 10 -max_line_length = 80 +max_line_length = 100 [sqlfluff:indentation] indented_joins = False diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_agg_projected_cash_flows_timeseries.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_agg_projected_cash_flows_timeseries.sql new file mode 100644 index 000000000..73ea7fb54 --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_agg_projected_cash_flows_timeseries.sql @@ -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 diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_agg_projected_cash_flows_tvm_risk.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_agg_projected_cash_flows_tvm_risk.sql new file mode 100644 index 000000000..161724850 --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_agg_projected_cash_flows_tvm_risk.sql @@ -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 diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_collaterals.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_collaterals.sql new file mode 100644 index 000000000..0f982b15b --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_collaterals.sql @@ -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 diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_denormalized.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_denormalized.sql new file mode 100644 index 000000000..9714b5cda --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_denormalized.sql @@ -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 diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_disbursals.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_disbursals.sql new file mode 100644 index 000000000..56948a21d --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_disbursals.sql @@ -0,0 +1,56 @@ +with disbursal_initiated 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(json_value(event, '$.amount') as numeric) as amount, + cast(json_value(event, '$.idx') as integer) as idx + from {{ ref('stg_credit_facility_events') }} as cfe + where cfe.event_type = 'disbursal_initiated' + +), + +disbursal_concluded 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, '$.idx') as integer) as idx, + parse_timestamp( + '%Y-%m-%dT%H:%M:%E*SZ', json_value(event, '$.recorded_at'), 'UTC' + ) as event_recorded_at + from {{ ref('stg_credit_facility_events') }} as cfe + where + cfe.event_type = 'disbursal_concluded' + and json_value(event, '$.tx_id') is not null + +) + + +select + di.* except (amount), + + dc.event_recorded_at as disbursal_concluded_event_recorded_at, + di.amount, + + coalesce(dc.event_recorded_at_date_key, 19000101) + as disbursal_concluded_event_recorded_at_date_key +from disbursal_initiated as di +left join + disbursal_concluded as dc + on di.event_id = dc.event_id and di.idx = dc.idx diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_flatten.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_flatten.sql new file mode 100644 index 000000000..93def8a50 --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_flatten.sql @@ -0,0 +1,80 @@ +with credit_facilities as ( + + select * from {{ ref('int_credit_facilities') }} + +), + +int_cf_disbursals as ( + + select + event_id, + max(recorded_at_date_key) as disbursal_recorded_at_date_key, + max(recorded_at) as disbursal_recorded_at, + max(disbursal_concluded_event_recorded_at_date_key) + as disbursal_concluded_event_recorded_at_date_key, + max(disbursal_concluded_event_recorded_at) + as disbursal_concluded_event_recorded_at, + sum(amount) as total_disbursed_amount + from {{ ref('int_cf_disbursals') }} + group by event_id + +), + +int_cf_collaterals as ( + + select + event_id, + max(recorded_at_date_key) as collateral_recorded_at_date_key, + max(recorded_at) as collateral_recorded_at, + + max(recorded_in_ledger_at_date_key) as recorded_in_ledger_at_date_key, + max(recorded_in_ledger_at) as recorded_in_ledger_at, + max(collateralization_changed_event_recorded_at_date_key) + as collateralization_changed_event_recorded_at_date_key, + max(collateralization_changed_event_recorded_at) + as collateralization_changed_event_recorded_at, + + array_agg( + collateralization_changed_state + order by collateralization_changed_event_recorded_at desc limit 1 + )[safe_ordinal(1)] as collateralization_changed_state, + + sum(diff) as total_collateral_summed, + array_agg( + total_collateral + order by recorded_at desc limit 1)[ + safe_ordinal(1) + ] as total_collateral, + + sum(outstanding_disbursed) as outstanding_disbursed, + sum(outstanding_interest) as outstanding_interest + from {{ ref('int_cf_collaterals') }} + group by event_id + +), + +int_cf_payments as ( + + select + event_id, + max(recorded_at_date_key) as payment_recorded_at_date_key, + max(recorded_at) as payment_recorded_at, + max(recorded_in_ledger_at_date_key) + as payment_recorded_in_ledger_at_date_key, + max(recorded_in_ledger_at) as payment_recorded_in_ledger_at, + sum(disbursement_amount) as disbursement_amount, + sum(interest_amount) as interest_amount + from {{ ref('int_cf_payments') }} + group by event_id + +) + +select + cfe.*, + d.* except (event_id), + c.* except (event_id), + p.* except (event_id) +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 diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_payments.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_payments.sql new file mode 100644 index 000000000..3b5c0395c --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_payments.sql @@ -0,0 +1,37 @@ +with payment_recorded 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, '$.disbursement_amount') as numeric) + as disbursement_amount, + cast(json_value(event, '$.interest_amount') as numeric) + as interest_amount, + parse_timestamp( + '%Y-%m-%dT%H:%M:%E*SZ', + json_value(event, '$.recorded_in_ledger_at'), + 'UTC' + ) as recorded_in_ledger_at + from {{ ref('stg_credit_facility_events') }} as cfe + where + cfe.event_type = 'payment_recorded' + and json_value(event, '$.tx_id') is not null + +) + + +select * +from payment_recorded diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_projected_cash_flows_common.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_projected_cash_flows_common.sql new file mode 100644 index 000000000..f6e8c2555 --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_projected_cash_flows_common.sql @@ -0,0 +1,213 @@ +with terms_and_disbursal as ( + select + *, + facility as credit_facility_limit_in_cents, + 'actual/360' as credit_facility_day_count_convention, + -- TODO get from proper source + amount as disbursal_amount_in_cents, + -- TODO get from proper source + disbursal_concluded_event_recorded_at as disbursal_start_date, + safe_divide(terms_annual_rate, 100.0) + as credit_facility_annual_interest_rate, + 5.53 / 100.0 as bench_mark_interest_rate, + timestamp(current_date()) as now_ts, + timestamp(date(activated_recorded_at)) as credit_facility_start_date, + case + when terms_duration_type = 'months' then + timestamp( + timestamp_add( + date(activated_recorded_at), + interval terms_duration_value month + ) + ) + end as credit_facility_end_date + from {{ ref('int_cf_denormalized') }} + where + disbursal_concluded_event_recorded_at_date_key != 19000101 + and terms_accrual_interval_type = 'end_of_month' +), + +projections as ( + select + *, + safe_divide( + credit_facility_annual_interest_rate, + case + when + ends_with(credit_facility_day_count_convention, '/360') + then 360.0 + when + ends_with(credit_facility_day_count_convention, '/365') + then 365.0 + else + timestamp_diff( + timestamp( + last_day(date(credit_facility_start_date), year) + ), + date_trunc(credit_facility_start_date, year), + day + ) + end + ) as credit_facility_daily_interest_rate, + safe_divide( + bench_mark_interest_rate, + case + when + ends_with(credit_facility_day_count_convention, '/360') + then 360.0 + when + ends_with(credit_facility_day_count_convention, '/365') + then 365.0 + else + timestamp_diff( + timestamp( + last_day(date(credit_facility_start_date), year) + ), + date_trunc(credit_facility_start_date, year), + day + ) + end + ) as bench_mark_daily_interest_rate, + case + when + ends_with(credit_facility_day_count_convention, '/360') + then 360.0 + when + ends_with(credit_facility_day_count_convention, '/365') + then 365.0 + else + timestamp_diff( + timestamp(last_day(date(credit_facility_start_date), year)), + date_trunc(credit_facility_start_date, year), + day + ) + end as days_per_year, + safe_divide( + bench_mark_interest_rate, credit_facility_annual_interest_rate + ) as breakeven_disbursal_percent, + safe_multiply( + credit_facility_limit_in_cents, + safe_divide( + bench_mark_interest_rate, credit_facility_annual_interest_rate + ) + ) as breakeven_disbursal_amount_in_cents, + case + when terms_accrual_interval_type = 'end_of_day' + then + generate_date_array( + date(disbursal_start_date), + last_day(date(credit_facility_end_date)), + interval 1 day + ) + when terms_accrual_interval_type = 'end_of_month' then + generate_date_array( + date(disbursal_start_date), + last_day(date(credit_facility_end_date)), + interval 1 month + ) + end as interest_schedule_months + from terms_and_disbursal +), + +projected_interest_payment_data as ( + select + p.* except (interest_schedule_months), + case + when + timestamp(date_trunc(projected_month, month)) + < disbursal_start_date + then + timestamp(date(disbursal_start_date)) + else + timestamp(date_trunc(projected_month, month)) + end as period_start_date, + case + when last_day(projected_month) > date(credit_facility_end_date) + then + timestamp(date(credit_facility_end_date)) + else + timestamp(last_day(projected_month)) + end as period_end_date, + 'projected_interest_payment' as payment_type + from projections as p, + unnest(interest_schedule_months) as projected_month +), + +projected_principal_payment_data as ( + select + * except (interest_schedule_months), + timestamp(date(disbursal_start_date)) as period_start_date, + timestamp(date(credit_facility_end_date)) as period_end_date, + 'projected_principal_payment' as payment_type + from projections +), + +projected_disbursal_data as ( + select + * except (interest_schedule_months), + timestamp(date(now_ts)) as period_start_date, + timestamp(timestamp_add(date(disbursal_start_date), interval -1 day)) + as period_end_date, + 'projected_disbursal' as payment_type + from projections +), + +projected_payment_data as ( + select * from projected_interest_payment_data + union all + select * from projected_principal_payment_data + union all + select * from projected_disbursal_data +), + +projected_time_data as ( + select + *, + cast( + timestamp_diff(date(period_end_date), date(now_ts), day) + + 1 as float64 + ) as days_from_now, + timestamp_diff(date(period_end_date), date(period_start_date), day) + + 1 as days_in_the_period + from projected_payment_data +), + +projected_cash_flows_common as ( + select + customer_id, + event_id, + idx as disbursal_idx, + credit_facility_start_date, + credit_facility_end_date, + bench_mark_interest_rate, + bench_mark_daily_interest_rate, + credit_facility_annual_interest_rate, + credit_facility_daily_interest_rate, + now_ts, + days_per_year, + days_in_the_period, + days_from_now, + case + when payment_type = 'projected_disbursal' + then cast(safe_negate(disbursal_amount_in_cents) as float64) + else 0 + end as projected_disbursal_amount_in_cents, + case + when payment_type = 'projected_interest_payment' + then + safe_multiply( + disbursal_amount_in_cents, + safe_multiply( + credit_facility_daily_interest_rate, + days_in_the_period + ) + ) + when payment_type = 'projected_principal_payment' + then disbursal_amount_in_cents + else 0 + end as projected_payment_amount_in_cents + from projected_time_data +) + +select * +from projected_cash_flows_common diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_projected_cash_flows_timeseries.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_projected_cash_flows_timeseries.sql new file mode 100644 index 000000000..3c464c8e3 --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_projected_cash_flows_timeseries.sql @@ -0,0 +1,42 @@ +with projected_cash_flows_common as ( + select * + from {{ ref('int_cf_projected_cash_flows_common') }} +), + +grouped as ( + select + customer_id, + event_id, + credit_facility_start_date, + credit_facility_end_date, + 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 + customer_id, + event_id, + credit_facility_start_date, + credit_facility_end_date, + 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 diff --git a/meltano/transform/models/intermediate/credit_facilities/int_cf_projected_cash_flows_tvm_risk.sql b/meltano/transform/models/intermediate/credit_facilities/int_cf_projected_cash_flows_tvm_risk.sql new file mode 100644 index 000000000..f84b0ffc4 --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_cf_projected_cash_flows_tvm_risk.sql @@ -0,0 +1,160 @@ +with projected_cash_flows_common as ( + select * + from {{ ref('int_cf_projected_cash_flows_common') }} +), + +grouped as ( + select + customer_id, + event_id, + credit_facility_start_date, + credit_facility_end_date, + 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 + customer_id, + event_id, + credit_facility_start_date, + credit_facility_end_date, + now_ts, + days_per_year, + bench_mark_daily_interest_rate, + days_from_now + order by days_from_now +), + +arrayed as ( + select + customer_id, + event_id, + credit_facility_start_date, + credit_facility_end_date, + 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 + customer_id, + event_id, + credit_facility_start_date, + credit_facility_end_date, + now_ts, + days_per_year, + bench_mark_daily_interest_rate +), + +with_risk as ( + select + customer_id, + event_id, + credit_facility_start_date, + credit_facility_end_date, + 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 + customer_id, + event_id, + credit_facility_start_date, + credit_facility_end_date, + 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 diff --git a/meltano/transform/models/intermediate/credit_facilities/int_credit_facilities.sql b/meltano/transform/models/intermediate/credit_facilities/int_credit_facilities.sql new file mode 100644 index 000000000..b8328a39b --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/int_credit_facilities.sql @@ -0,0 +1,134 @@ +with initialized 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(json_value(event, '$.terms.annual_rate') as numeric) + as terms_annual_rate, + cast(json_value(event, '$.terms.duration.value') as integer) + as terms_duration_value, + cast(json_value(event, '$.terms.initial_cvl') as numeric) + as terms_initial_cvl, + cast(json_value(event, '$.terms.liquidation_cvl') as numeric) + as terms_liquidation_cvl, + cast(json_value(event, '$.terms.margin_call_cvl') as numeric) + as terms_margin_call_cvl, + cast(json_value(event, '$.facility') as numeric) as facility, + json_value(event, '$.customer_id') as customer_id, + json_value(event, '$.terms.accrual_interval.type') + as terms_accrual_interval_type, + json_value(event, '$.terms.duration.type') as terms_duration_type, + json_value(event, '$.terms.incurrence_interval.type') + as terms_incurrence_interval_type + from {{ ref('stg_credit_facility_events') }} as cfe + where cfe.event_type = 'initialized' + +), + +approval_process_started as ( + + select + id as event_id, + cast(format_date('%Y%m%d', recorded_at) as int64) + as recorded_at_date_key, + recorded_at + from {{ ref('stg_credit_facility_events') }} as cfe + where cfe.event_type = 'approval_process_started' + +), + +approval_process_concluded as ( + + select + id as event_id, + cast(format_date('%Y%m%d', recorded_at) as int64) + as recorded_at_date_key, + recorded_at, + cast(json_value(event, '$.approved') as boolean) as approved + from {{ ref('stg_credit_facility_events') }} as cfe + where cfe.event_type = 'approval_process_concluded' + +), + +activated 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, '$.activated_at') + ), + 'UTC' + ) as int64 + ) as activated_at_date_key, + parse_timestamp( + '%Y-%m-%dT%H:%M:%E*SZ', json_value(event, '$.activated_at'), 'UTC' + ) as activated_at + from {{ ref('stg_credit_facility_events') }} as cfe + where cfe.event_type = 'activated' + +), + +completed 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, '$.completed_at') + ), + 'UTC' + ) as int64 + ) as completed_at_date_key, + parse_timestamp( + '%Y-%m-%dT%H:%M:%E*SZ', json_value(event, '$.completed_at'), 'UTC' + ) as completed_at + from {{ ref('stg_credit_facility_events') }} as cfe + where cfe.event_type = 'completed' + +) + + +select + i.* except (facility), + + aps.recorded_at as approval_process_started_recorded_at, + apc.recorded_at as approval_process_concluded_recorded_at, + + a.recorded_at as activated_recorded_at, + a.activated_at, + c.recorded_at as completed_recorded_at, + + c.completed_at, + i.facility, + coalesce(aps.recorded_at_date_key, 19000101) + as approval_process_started_recorded_at_date_key, + coalesce(apc.recorded_at_date_key, 19000101) + as approval_process_concluded_recorded_at_date_key, + + coalesce(apc.approved, false) as approval_process_concluded_approved, + coalesce(a.recorded_at_date_key, 19000101) + as activated_recorded_at_date_key, + coalesce(a.activated_at_date_key, 19000101) as activated_at_date_key, + coalesce(c.recorded_at_date_key, 19000101) + as completed_recorded_at_date_key, + + coalesce(c.completed_at_date_key, 19000101) as completed_at_date_key +from initialized as i +left join approval_process_started as aps on i.event_id = aps.event_id +left join approval_process_concluded as apc on i.event_id = apc.event_id +left join activated as a on i.event_id = a.event_id +left join completed as c on i.event_id = c.event_id diff --git a/meltano/transform/models/intermediate/credit_facilities/risk_management/int_credit_facilities_in_numbers.sql b/meltano/transform/models/intermediate/credit_facilities/risk_management/int_credit_facilities_in_numbers.sql new file mode 100644 index 000000000..1b2631cbd --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/risk_management/int_credit_facilities_in_numbers.sql @@ -0,0 +1,31 @@ +with approved as ( + select count(distinct event_id) as the_value + from {{ ref("int_credit_facilities") }} + where approval_process_concluded_approved +), + +total as ( + select count(distinct event_id) as the_value + from {{ ref("int_credit_facilities") }} +) + + +select + 1 as order_by, + cast(the_value as string) as the_value, + 'Number of Approved Credit Facilities' as the_name +from approved +union all +select + 2 as order_by, + cast(the_value as string) as the_value, + 'Number of Total Credit Facilities' as the_name +from total +union all +select + 3 as order_by, + cast(a.the_value / t.the_value as string) as the_value, + 'Approved Rate' as the_name +from approved as a, total as t + +order by order_by diff --git a/meltano/transform/models/intermediate/credit_facilities/risk_management/int_credit_facilities_in_time_value_of_money.sql b/meltano/transform/models/intermediate/credit_facilities/risk_management/int_credit_facilities_in_time_value_of_money.sql new file mode 100644 index 000000000..6754caca5 --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/risk_management/int_credit_facilities_in_time_value_of_money.sql @@ -0,0 +1,60 @@ +with final as ( + select * from {{ ref("int_cf_agg_projected_cash_flows_tvm_risk") }} +) + + +select + 0 as order_by, + cast(disbursal_pv as string) as the_value, + 'Present Value of disbursal cashflows' as the_name +from final +union all +select + 1 as order_by, + cast(pv as string) as the_value, + 'Present Value of future cashflows' as the_name +from final +union all +select + 2 as order_by, + cast(npv as string) as the_value, + 'Net Present Value of disbursal & future cashflows' as the_name +from final +union all +select + 3 as order_by, + cast(ytm as string) as the_value, + 'YTM' as the_name +from final +union all +select + 4 as order_by, + cast(ytm_from_price as string) as the_value, + 'YTM @ disbursal pv' as the_name +from final +union all +select + 5 as order_by, + cast(mac_duration as string) as the_value, + 'MacDuration' as the_name +from final +union all +select + 6 as order_by, + cast(mac_duration_date as string) as the_value, + 'MacDurationDate' as the_name +from final +union all +select + 7 as order_by, + cast(dv01 as string) as the_value, + 'DV01' as the_name +from final +union all +select + 8 as order_by, + cast(pv_at_dv01 as string) as the_value, + 'PV @ DV01' as the_name +from final + +order by order_by diff --git a/meltano/transform/models/intermediate/credit_facilities/risk_management/int_credit_facilities_in_values.sql b/meltano/transform/models/intermediate/credit_facilities/risk_management/int_credit_facilities_in_values.sql new file mode 100644 index 000000000..d093fc6f0 --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/risk_management/int_credit_facilities_in_values.sql @@ -0,0 +1,123 @@ +with value_approved_cf as ( + select safe_divide(sum(facility), 100.0) as amount_in_usd + from {{ ref("int_credit_facilities") }} + where approval_process_concluded_approved +), + +disbursed as ( + select safe_divide(sum(amount), 100.0) as amount_in_usd + from {{ ref("int_cf_disbursals") }} + where disbursal_concluded_event_recorded_at_date_key != 19000101 +), + +breakeven as ( + select + cfe.event_id, + 5.53 as bench_mark, -- TODO get from proper source + cfe.terms_annual_rate, + facility as credit_facility_limit_in_cents, + coalesce(amount, 0) as disbursal_amount_in_cents + from {{ ref("int_cf_denormalized") }} as cfe + where + approval_process_concluded_approved + and facility > 0 +), + +breakeven_by_cf as ( + select + event_id, + bench_mark, + terms_annual_rate, + credit_facility_limit_in_cents, + sum(disbursal_amount_in_cents) as disbursal_amount_in_cents + from breakeven + group by + event_id, + bench_mark, + terms_annual_rate, + credit_facility_limit_in_cents +), + +breakeven_ratio as ( + select + event_id, + bench_mark, + terms_annual_rate, + disbursal_amount_in_cents, + credit_facility_limit_in_cents, + bench_mark / 100.0 as bench_mark_interest_rate, + safe_divide( + credit_facility_limit_in_cents, + sum(credit_facility_limit_in_cents) over () + ) as facility_limit_ratio, + safe_divide(disbursal_amount_in_cents, credit_facility_limit_in_cents) + as disbursal_ratio, + safe_divide(bench_mark, terms_annual_rate) as breakeven_disbursal_ratio + from breakeven_by_cf +), + +breakeven_prop as ( + select + event_id, + bench_mark, + terms_annual_rate, + disbursal_amount_in_cents, + credit_facility_limit_in_cents, + bench_mark_interest_rate, + facility_limit_ratio, + disbursal_ratio, + breakeven_disbursal_ratio, + safe_multiply(breakeven_disbursal_ratio, facility_limit_ratio) + as prop_breakeven_disbursal_ratio, + safe_multiply(disbursal_ratio, facility_limit_ratio) + as prop_disbursal_ratio + from breakeven_ratio +), + +breakeven_sum as ( + select + bench_mark, + sum(prop_breakeven_disbursal_ratio) as breakeven_disbursal_ratio, + sum(prop_disbursal_ratio) as disbursal_ratio + from breakeven_prop + group by bench_mark +) + + +select + 1 as order_by, + cast(amount_in_usd as string) as the_value, + 'Total Value of Approved Credit Facilities' as the_name +from value_approved_cf +union all +select + 2 as order_by, + cast(amount_in_usd as string) as the_value, + 'Total Value Disbursed from Approved Credit Facilities' as the_name +from disbursed +union all +select + 3 as order_by, + cast(safe_subtract(v.amount_in_usd, d.amount_in_usd) as string) as the_value, + 'Total Value NOT-YET Disbursed from Approved Credit Facilities' as the_name +from value_approved_cf as v, disbursed as d +union all +select + 4 as order_by, + cast(safe_divide(d.amount_in_usd, v.amount_in_usd) * 100 as string) as the_value, + 'Disbursed-to-Approved ratio (%)' as the_name +from value_approved_cf as v, disbursed as d +union all +select + 5 as order_by, + cast(disbursal_ratio * 100 as string) as the_value, + 'Disbursal ratio (%) - proportional' as the_name +from breakeven_sum +union all +select + 6 as order_by, + cast(breakeven_disbursal_ratio * 100 as string) as the_value, + 'Breakeven ratio (%) - proportional @' || bench_mark || '% benchmark' as the_name +from breakeven_sum + +order by order_by diff --git a/meltano/transform/models/intermediate/credit_facilities/risk_management/int_customers_in_numbers.sql b/meltano/transform/models/intermediate/credit_facilities/risk_management/int_customers_in_numbers.sql new file mode 100644 index 000000000..fbe9ce5df --- /dev/null +++ b/meltano/transform/models/intermediate/credit_facilities/risk_management/int_customers_in_numbers.sql @@ -0,0 +1,49 @@ +with total_customers as ( + select count(distinct customer_id) as the_value + from {{ ref("int_credit_facilities") }} +), + +total_active_customers as ( + select count(distinct customer_id) as the_value + from {{ ref("int_credit_facilities") }} + where completed_recorded_at is null +), + +approved_cf as ( + select count(distinct customer_id) as the_value + from {{ ref("int_credit_facilities") }} + where approval_process_concluded_approved +), + +disbursed_cf as ( + select count(distinct customer_id) as the_value + from {{ ref("int_cf_denormalized") }} + where disbursal_concluded_event_recorded_at_date_key != 19000101 +) + + +select + 1 as order_by, + cast(the_value as string) as the_value, + 'Total Number of Customers' as the_name +from total_customers +union all +select + 1 as order_by, + cast(the_value as string) as the_value, + 'Total Number of Active Customers' as the_name +from total_active_customers +union all +select + 2 as order_by, + cast(the_value as string) as the_value, + 'Total Number of Customers with Approved Credit Facilities' as the_name +from approved_cf +union all +select + 3 as order_by, + cast(the_value as string) as the_value, + 'Total Number of Customers with Disbursed Approved Credit Facilities' as the_name +from disbursed_cf + +order by order_by diff --git a/meltano/transform/models/outputs/risk_management/kpi_credit_facilities.sql b/meltano/transform/models/outputs/risk_management/kpi_credit_facilities.sql new file mode 100644 index 000000000..c47cf0e6e --- /dev/null +++ b/meltano/transform/models/outputs/risk_management/kpi_credit_facilities.sql @@ -0,0 +1,35 @@ +with this as ( + select + the_name, + the_value, + order_by, + 1 as rpt_order + from {{ ref('int_customers_in_numbers') }} + union all + select + the_name, + the_value, + order_by, + 2 as rpt_order + from {{ ref('int_credit_facilities_in_numbers') }} + union all + select + the_name, + the_value, + order_by, + 3 as rpt_order + from {{ ref('int_credit_facilities_in_values') }} + union all + select + the_name, + the_value, + order_by, + 4 as rpt_order + from {{ ref('int_credit_facilities_in_time_value_of_money') }} + order by rpt_order, order_by +) + +select + the_name, + the_value +from this