feat: Implement currency management with models, routes, and UI updates; add backfill script for existing records

This commit is contained in:
2025-10-21 10:33:08 +02:00
parent fcea39deb0
commit 672cafa5b9
14 changed files with 478 additions and 10 deletions

View File

@@ -0,0 +1,103 @@
"""
Backfill script to populate currency_id for capex and opex rows using existing currency_code.
Usage:
python scripts/backfill_currency.py --dry-run
python scripts/backfill_currency.py --create-missing
This script is intentionally cautious: it defaults to dry-run mode and will refuse to run
if DATABASE_URL is not set. It supports creating missing currency rows when `--create-missing`
is provided. Always run against a development/staging database first.
"""
from __future__ import annotations
import os
import argparse
from sqlalchemy import text, create_engine
def load_env_dburl() -> str:
db = os.environ.get("DATABASE_URL")
if not db:
raise RuntimeError(
"DATABASE_URL not set — set it to your dev/staging DB before running this script")
return db
def backfill(db_url: str, dry_run: bool = True, create_missing: bool = False) -> None:
engine = create_engine(db_url)
with engine.begin() as conn:
# Ensure currency table exists
res = conn.execute(text("SELECT name FROM sqlite_master WHERE type='table' AND name='currency';")) if db_url.startswith(
'sqlite:') else conn.execute(text("SELECT to_regclass('public.currency');"))
# Note: we don't strictly depend on the above - we assume migration was already applied
# Helper: find or create currency by code
def find_currency_id(code: str):
r = conn.execute(text("SELECT id FROM currency WHERE code = :code"), {
"code": code}).fetchone()
if r:
return r[0]
if create_missing:
# insert and return id
conn.execute(text("INSERT INTO currency (code, name, symbol, is_active) VALUES (:c, :n, NULL, TRUE)"), {
"c": code, "n": code})
if db_url.startswith('sqlite:'):
r2 = conn.execute(text("SELECT id FROM currency WHERE code = :code"), {
"code": code}).fetchone()
else:
r2 = conn.execute(text("SELECT id FROM currency WHERE code = :code"), {
"code": code}).fetchone()
return r2[0]
return None
# Process tables capex and opex
for table in ("capex", "opex"):
# Check if currency_id column exists
try:
cols = conn.execute(text(f"SELECT 1 FROM information_schema.columns WHERE table_name = '{table}' AND column_name = 'currency_id'")) if not db_url.startswith(
'sqlite:') else [(1,)]
except Exception:
cols = [(1,)]
if not cols:
print(f"Skipping {table}: no currency_id column found")
continue
# Find rows where currency_id IS NULL but currency_code exists
rows = conn.execute(text(
f"SELECT id, currency_code FROM {table} WHERE currency_id IS NULL OR currency_id = ''"))
changed = 0
for r in rows:
rid = r[0]
code = (r[1] or "USD").strip().upper()
cid = find_currency_id(code)
if cid is None:
print(
f"Row {table}:{rid} has unknown currency code '{code}' and create_missing=False; skipping")
continue
if dry_run:
print(
f"[DRY RUN] Would set {table}.currency_id = {cid} for row id={rid} (code={code})")
else:
conn.execute(text(f"UPDATE {table} SET currency_id = :cid WHERE id = :rid"), {
"cid": cid, "rid": rid})
changed += 1
print(f"{table}: processed, changed={changed} (dry_run={dry_run})")
def main() -> None:
parser = argparse.ArgumentParser(
description="Backfill currency_id from currency_code for capex/opex tables")
parser.add_argument("--dry-run", action="store_true",
default=True, help="Show actions without writing")
parser.add_argument("--create-missing", action="store_true",
help="Create missing currency rows in the currency table")
args = parser.parse_args()
db = load_env_dburl()
backfill(db, dry_run=args.dry_run, create_missing=args.create_missing)
if __name__ == "__main__":
main()

View File

@@ -0,0 +1,29 @@
-- CalMiner Migration: add currency and unit metadata columns
-- Date: 2025-10-21
-- Purpose: align persisted schema with API changes introducing currency selection for
-- CAPEX/OPEX costs and unit selection for consumption/production records.
BEGIN;
-- CAPEX / OPEX
ALTER TABLE capex
ADD COLUMN currency_code VARCHAR(3) NOT NULL DEFAULT 'USD';
ALTER TABLE opex
ADD COLUMN currency_code VARCHAR(3) NOT NULL DEFAULT 'USD';
-- Consumption tracking
ALTER TABLE consumption
ADD COLUMN unit_name VARCHAR(64);
ALTER TABLE consumption
ADD COLUMN unit_symbol VARCHAR(16);
-- Production output
ALTER TABLE production_output
ADD COLUMN unit_name VARCHAR(64);
ALTER TABLE production_output
ADD COLUMN unit_symbol VARCHAR(16);
COMMIT;

View File

@@ -0,0 +1,66 @@
-- Migration: create currency referential table and convert capex/opex to FK
-- Date: 2025-10-22
BEGIN;
-- 1) Create currency table
CREATE TABLE IF NOT EXISTS currency (
id SERIAL PRIMARY KEY,
code VARCHAR(3) NOT NULL UNIQUE,
name VARCHAR(128) NOT NULL,
symbol VARCHAR(8),
is_active BOOLEAN NOT NULL DEFAULT TRUE
);
-- 2) Seed some common currencies (idempotent)
INSERT INTO currency (code, name, symbol, is_active)
SELECT * FROM (VALUES
('USD','United States Dollar','$',TRUE),
('EUR','Euro','',TRUE),
('CLP','Chilean Peso','CLP$',TRUE),
('RMB','Chinese Yuan','¥',TRUE),
('GBP','British Pound','£',TRUE),
('CAD','Canadian Dollar','C$',TRUE),
('AUD','Australian Dollar','A$',TRUE)
) AS v(code,name,symbol,is_active)
ON CONFLICT (code) DO NOTHING;
-- 3) Add currency_id columns to capex and opex with nullable true to allow backfill
ALTER TABLE capex ADD COLUMN IF NOT EXISTS currency_id INTEGER;
ALTER TABLE opex ADD COLUMN IF NOT EXISTS currency_id INTEGER;
-- 4) Backfill currency_id using existing currency_code column where present
-- Only do this if the currency_code column exists
DO $$
BEGIN
IF EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name='capex' AND column_name='currency_code') THEN
UPDATE capex SET currency_id = (
SELECT id FROM currency WHERE code = capex.currency_code LIMIT 1
);
END IF;
IF EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name='opex' AND column_name='currency_code') THEN
UPDATE opex SET currency_id = (
SELECT id FROM currency WHERE code = opex.currency_code LIMIT 1
);
END IF;
END$$;
-- 5) Make currency_id non-nullable and add FK constraint, default to USD where missing
UPDATE currency SET is_active = TRUE WHERE code = 'USD';
-- Ensure any NULL currency_id uses USD
UPDATE capex SET currency_id = (SELECT id FROM currency WHERE code='USD') WHERE currency_id IS NULL;
UPDATE opex SET currency_id = (SELECT id FROM currency WHERE code='USD') WHERE currency_id IS NULL;
ALTER TABLE capex ALTER COLUMN currency_id SET NOT NULL;
ALTER TABLE opex ALTER COLUMN currency_id SET NOT NULL;
ALTER TABLE capex ADD CONSTRAINT fk_capex_currency FOREIGN KEY (currency_id) REFERENCES currency(id);
ALTER TABLE opex ADD CONSTRAINT fk_opex_currency FOREIGN KEY (currency_id) REFERENCES currency(id);
-- 6) Optionally drop old currency_code columns if they exist
ALTER TABLE capex DROP COLUMN IF EXISTS currency_code;
ALTER TABLE opex DROP COLUMN IF EXISTS currency_code;
COMMIT;