REFACTOR Migrates to single 'amount' field for transactions

Refactors the data model to use a single 'amount' field for journal entry lines, aligning with the Beancount approach.
This simplifies the model, enhances compatibility, and eliminates invalid states.

Includes a database migration to convert existing debit/credit columns to the new 'amount' field.

Updates balance calculation logic to utilize the new amount field for improved accuracy and efficiency.
This commit is contained in:
padreug 2025-11-08 10:26:14 +01:00
parent 0b50ba0f82
commit 5cc2630777
7 changed files with 196 additions and 144 deletions

View file

@ -541,3 +541,90 @@ async def m014_remove_legacy_equity_accounts(db):
"DELETE FROM accounts WHERE name = :name",
{"name": "Equity:RetainedEarnings"}
)
async def m015_convert_to_single_amount_field(db):
"""
Convert entry_lines from separate debit/credit columns to single amount field.
This aligns Castle with Beancount's elegant design:
- Positive amount = debit (increase assets/expenses, decrease liabilities/equity/revenue)
- Negative amount = credit (decrease assets/expenses, increase liabilities/equity/revenue)
Benefits:
- Simpler model (one field instead of two)
- Direct compatibility with Beancount import/export
- Eliminates invalid states (both debit and credit non-zero)
- More intuitive for programmers (positive/negative instead of accounting conventions)
Migration formula: amount = debit - credit
Examples:
- Expense transaction:
* Expenses:Food:Groceries amount=+100 (debit)
* Liabilities:Payable:User amount=-100 (credit)
- Payment transaction:
* Liabilities:Payable:User amount=+100 (debit)
* Assets:Bitcoin:Lightning amount=-100 (credit)
"""
from sqlalchemy.exc import OperationalError
# Step 1: Add new amount column (nullable for migration)
try:
await db.execute(
"ALTER TABLE entry_lines ADD COLUMN amount INTEGER"
)
except OperationalError:
# Column might already exist if migration was partially run
pass
# Step 2: Populate amount from existing debit/credit
# Formula: amount = debit - credit
await db.execute(
"""
UPDATE entry_lines
SET amount = debit - credit
WHERE amount IS NULL
"""
)
# Step 3: Create new table with amount field as NOT NULL
# SQLite doesn't support ALTER COLUMN, so we need to recreate the table
await db.execute(
"""
CREATE TABLE entry_lines_new (
id TEXT PRIMARY KEY,
journal_entry_id TEXT NOT NULL,
account_id TEXT NOT NULL,
amount INTEGER NOT NULL,
description TEXT,
metadata TEXT DEFAULT '{}'
)
"""
)
# Step 4: Copy data from old table to new
await db.execute(
"""
INSERT INTO entry_lines_new (id, journal_entry_id, account_id, amount, description, metadata)
SELECT id, journal_entry_id, account_id, amount, description, metadata
FROM entry_lines
"""
)
# Step 5: Drop old table and rename new one
await db.execute("DROP TABLE entry_lines")
await db.execute("ALTER TABLE entry_lines_new RENAME TO entry_lines")
# Step 6: Recreate indexes
await db.execute(
"""
CREATE INDEX idx_entry_lines_journal_entry ON entry_lines (journal_entry_id)
"""
)
await db.execute(
"""
CREATE INDEX idx_entry_lines_account ON entry_lines (account_id)
"""
)