From ecc669d4a85e724154ae59a64f94f096c6babc95 Mon Sep 17 00:00:00 2001 From: Zach Gollwitzer Date: Sun, 20 Jul 2025 06:32:04 -0400 Subject: [PATCH] Add new balance components --- ...21103_add_start_end_columns_to_balances.rb | 102 ++---------------- db/schema.rb | 7 +- 2 files changed, 12 insertions(+), 97 deletions(-) diff --git a/db/migrate/20250719121103_add_start_end_columns_to_balances.rb b/db/migrate/20250719121103_add_start_end_columns_to_balances.rb index 2d1b6c32..1c864439 100644 --- a/db/migrate/20250719121103_add_start_end_columns_to_balances.rb +++ b/db/migrate/20250719121103_add_start_end_columns_to_balances.rb @@ -1,9 +1,5 @@ class AddStartEndColumnsToBalances < ActiveRecord::Migration[7.2] def up - # Rename existing columns to deprecated versions - # rename_column :balances, :balance, :balance_deprecated - # rename_column :balances, :cash_balance, :cash_balance_deprecated - # Add new columns for balance tracking add_column :balances, :start_cash_balance, :decimal, precision: 19, scale: 4, null: false, default: 0.0 add_column :balances, :start_non_cash_balance, :decimal, precision: 19, scale: 4, null: false, default: 0.0 @@ -21,16 +17,20 @@ class AddStartEndColumnsToBalances < ActiveRecord::Migration[7.2] add_column :balances, :cash_adjustments, :decimal, precision: 19, scale: 4, null: false, default: 0.0 add_column :balances, :non_cash_adjustments, :decimal, precision: 19, scale: 4, null: false, default: 0.0 + # Flows factor determines *how* the flows affect the balance. + # Inflows increase asset accounts, while inflows decrease liability accounts (reducing debt via "payment") + add_column :balances, :flows_factor, :integer, null: false, default: 1 + # Add generated columns change_table :balances do |t| t.virtual :start_balance, type: :decimal, precision: 19, scale: 4, stored: true, as: "start_cash_balance + start_non_cash_balance" t.virtual :end_cash_balance, type: :decimal, precision: 19, scale: 4, stored: true, - as: "start_cash_balance + cash_inflows - cash_outflows + cash_adjustments" + as: "start_cash_balance + ((cash_inflows - cash_outflows) * flows_factor) + cash_adjustments" t.virtual :end_non_cash_balance, type: :decimal, precision: 19, scale: 4, stored: true, - as: "start_non_cash_balance + non_cash_inflows - non_cash_outflows + net_market_flows + non_cash_adjustments" + as: "start_non_cash_balance + ((non_cash_inflows - non_cash_outflows) * flows_factor) + net_market_flows + non_cash_adjustments" # Postgres doesn't support generated columns depending on other generated columns, # but we want the integrity of the data to happen at the DB level, so this is the full formula. @@ -39,98 +39,16 @@ class AddStartEndColumnsToBalances < ActiveRecord::Migration[7.2] as: <<~SQL.squish ( start_cash_balance + - cash_inflows - - cash_outflows + + ((cash_inflows - cash_outflows) * flows_factor) + cash_adjustments ) + ( start_non_cash_balance + - non_cash_inflows - - non_cash_outflows + + ((non_cash_inflows - non_cash_outflows) * flows_factor) + net_market_flows + non_cash_adjustments ) SQL end - - # Migrate existing data - - # Step 1: Set start values using LOCF (Last Observation Carried Forward) - execute <<~SQL - UPDATE balances b1 - SET - start_cash_balance = COALESCE(prev.cash_balance, 0), - start_non_cash_balance = COALESCE(prev.balance - prev.cash_balance, 0) - FROM balances b1_inner - LEFT JOIN LATERAL ( - SELECT - b2.cash_balance, - b2.balance - FROM balances b2 - WHERE b2.account_id = b1_inner.account_id - AND b2.currency = b1_inner.currency - AND b2.date < b1_inner.date - ORDER BY b2.date DESC - LIMIT 1 - ) prev ON true - WHERE b1.id = b1_inner.id - SQL - - # Step 2: Calculate net flows as inflows (can be negative) - # We use net change as inflows, outflows stay 0 for historical data - execute <<~SQL - UPDATE balances SET - cash_inflows = cash_balance - start_cash_balance, - cash_outflows = 0, - non_cash_inflows = (balance - cash_balance) - start_non_cash_balance, - non_cash_outflows = 0, - net_market_flows = 0 - SQL - - # Step 3: Initialize adjustments to 0 - execute <<~SQL - UPDATE balances SET - cash_adjustments = 0, - non_cash_adjustments = 0 - SQL - - # Step 4: Calculate adjustments from valuation entries - execute <<~SQL - WITH valuation_data AS ( - SELECT#{' '} - e.account_id, - e.date, - e.amount as valuation_amount, - e.currency, - a.accountable_type - FROM entries e - JOIN accounts a ON a.id = e.account_id - WHERE e.entryable_type = 'Valuation' - ) - UPDATE balances b - SET - cash_adjustments = CASE - -- For investment accounts: valuation sets total, preserve holdings value - WHEN vd.accountable_type = 'Investment' THEN - vd.valuation_amount - (b.start_balance + b.cash_inflows + b.non_cash_inflows) - -- For loan accounts: adjustment goes to non-cash - WHEN vd.accountable_type = 'Loan' THEN - 0 - -- For all other accounts: adjustment goes to cash - ELSE - vd.valuation_amount - (b.start_balance + b.cash_inflows + b.non_cash_inflows) - END, - non_cash_adjustments = CASE - -- Only loan accounts get non-cash adjustments - WHEN vd.accountable_type = 'Loan' THEN - vd.valuation_amount - (b.start_balance + b.cash_inflows + b.non_cash_inflows) - ELSE - 0 - END - FROM valuation_data vd - WHERE b.account_id = vd.account_id - AND b.date = vd.date - AND b.currency = vd.currency - SQL end def down @@ -150,9 +68,5 @@ class AddStartEndColumnsToBalances < ActiveRecord::Migration[7.2] remove_column :balances, :net_market_flows remove_column :balances, :cash_adjustments remove_column :balances, :non_cash_adjustments - - # Restore original column names - # rename_column :balances, :balance_deprecated, :balance - # rename_column :balances, :cash_balance_deprecated, :cash_balance end end diff --git a/db/schema.rb b/db/schema.rb index d99ac8f7..39f0eeb0 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -124,10 +124,11 @@ ActiveRecord::Schema[7.2].define(version: 2025_07_19_121103) do t.decimal "net_market_flows", precision: 19, scale: 4, default: "0.0", null: false t.decimal "cash_adjustments", precision: 19, scale: 4, default: "0.0", null: false t.decimal "non_cash_adjustments", precision: 19, scale: 4, default: "0.0", null: false + t.integer "flows_factor", default: 1, null: false t.virtual "start_balance", type: :decimal, precision: 19, scale: 4, as: "(start_cash_balance + start_non_cash_balance)", stored: true - t.virtual "end_cash_balance", type: :decimal, precision: 19, scale: 4, as: "(((start_cash_balance + cash_inflows) - cash_outflows) + cash_adjustments)", stored: true - t.virtual "end_non_cash_balance", type: :decimal, precision: 19, scale: 4, as: "((((start_non_cash_balance + non_cash_inflows) - non_cash_outflows) + net_market_flows) + non_cash_adjustments)", stored: true - t.virtual "end_balance", type: :decimal, precision: 19, scale: 4, as: "((((start_cash_balance + cash_inflows) - cash_outflows) + cash_adjustments) + ((((start_non_cash_balance + non_cash_inflows) - non_cash_outflows) + net_market_flows) + non_cash_adjustments))", stored: true + t.virtual "end_cash_balance", type: :decimal, precision: 19, scale: 4, as: "((start_cash_balance + ((cash_inflows - cash_outflows) * (flows_factor)::numeric)) + cash_adjustments)", stored: true + t.virtual "end_non_cash_balance", type: :decimal, precision: 19, scale: 4, as: "(((start_non_cash_balance + ((non_cash_inflows - non_cash_outflows) * (flows_factor)::numeric)) + net_market_flows) + non_cash_adjustments)", stored: true + t.virtual "end_balance", type: :decimal, precision: 19, scale: 4, as: "(((start_cash_balance + ((cash_inflows - cash_outflows) * (flows_factor)::numeric)) + cash_adjustments) + (((start_non_cash_balance + ((non_cash_inflows - non_cash_outflows) * (flows_factor)::numeric)) + net_market_flows) + non_cash_adjustments))", stored: true t.index ["account_id", "date", "currency"], name: "index_account_balances_on_account_id_date_currency_unique", unique: true t.index ["account_id", "date"], name: "index_balances_on_account_id_and_date", order: { date: :desc } t.index ["account_id"], name: "index_balances_on_account_id"