diff --git a/docs/architecture.md b/docs/architecture.md index 9ed684d..dfb6101 100644 --- a/docs/architecture.md +++ b/docs/architecture.md @@ -12,7 +12,7 @@ The backend leverages SQLAlchemy for ORM mapping to a PostgreSQL database. - **FastAPI backend** (`main.py`, `routes/`): hosts REST endpoints for scenarios, parameters, costs, consumption, production, equipment, maintenance, simulations, and reporting. Each router encapsulates request/response schemas and DB access patterns, leveraging a shared dependency module (`routes/dependencies.get_db`) for SQLAlchemy session management. - **Service layer** (`services/`): houses business logic. `services/reporting.py` produces statistical summaries, while `services/simulation.py` provides the Monte Carlo integration point. -- **Persistence** (`models/`, `config/database.py`): SQLAlchemy models map to PostgreSQL tables in schema `bricsium_platform`. Relationships connect scenarios to derived domain entities. +- **Persistence** (`models/`, `config/database.py`): SQLAlchemy models map to PostgreSQL tables. Relationships connect scenarios to derived domain entities. - **Presentation** (`templates/`, `components/`): server-rendered views extend a shared `base.html` layout with a persistent left sidebar, pull global styles from `static/css/main.css`, and surface data entry (scenario and parameter forms) alongside the Chart.js-powered dashboard. - **Reusable partials** (`templates/partials/components.html`): macro library that standardises select inputs, feedback/empty states, and table wrappers so pages remain consistent while keeping DOM hooks stable for existing JavaScript modules. - **Middleware** (`middleware/validation.py`): applies JSON validation before requests reach routers. diff --git a/models/__init__.py b/models/__init__.py new file mode 100644 index 0000000..69b5612 --- /dev/null +++ b/models/__init__.py @@ -0,0 +1,5 @@ +""" +models package initializer. Import the currency model so it's registered +with the shared Base.metadata when the package is imported by tests. +""" +from . import currency # noqa: F401 diff --git a/models/capex.py b/models/capex.py index f926daf..6b68f4c 100644 --- a/models/capex.py +++ b/models/capex.py @@ -1,3 +1,4 @@ +from sqlalchemy import event, text from sqlalchemy import Column, Integer, Float, String, ForeignKey from sqlalchemy.orm import relationship from config.database import Base @@ -10,12 +11,55 @@ class Capex(Base): scenario_id = Column(Integer, ForeignKey("scenario.id"), nullable=False) amount = Column(Float, nullable=False) description = Column(String, nullable=True) - currency_code = Column(String(3), nullable=False, default="USD") + currency_id = Column(Integer, ForeignKey("currency.id"), nullable=False) scenario = relationship("Scenario", back_populates="capex_items") + currency = relationship("Currency", back_populates="capex_items") def __repr__(self): return ( f"" + f"amount={self.amount} currency_id={self.currency_id}>" ) + + @property + def currency_code(self) -> str: + return self.currency.code if self.currency else None + + @currency_code.setter + def currency_code(self, value: str) -> None: + # store pending code so application code or migrations can pick it up + setattr(self, "_currency_code_pending", + (value or "USD").strip().upper()) + + +# SQLAlchemy event handlers to ensure currency_id is set before insert/update + + +def _resolve_currency(mapper, connection, target): + # If currency_id already set, nothing to do + if getattr(target, "currency_id", None): + return + code = getattr(target, "_currency_code_pending", None) or "USD" + # Try to find existing currency id + row = connection.execute(text("SELECT id FROM currency WHERE code = :code"), { + "code": code}).fetchone() + if row: + cid = row[0] + else: + # Insert new currency and attempt to get lastrowid + res = connection.execute( + text("INSERT INTO currency (code, name, symbol, is_active) VALUES (:code, :name, :symbol, :active)"), + {"code": code, "name": code, "symbol": None, "active": True}, + ) + try: + cid = res.lastrowid + except Exception: + # fallback: select after insert + cid = connection.execute(text("SELECT id FROM currency WHERE code = :code"), { + "code": code}).scalar() + target.currency_id = cid + + +event.listen(Capex, "before_insert", _resolve_currency) +event.listen(Capex, "before_update", _resolve_currency) diff --git a/models/currency.py b/models/currency.py new file mode 100644 index 0000000..b280c2d --- /dev/null +++ b/models/currency.py @@ -0,0 +1,21 @@ +from sqlalchemy import Column, Integer, String, Boolean +from sqlalchemy.orm import relationship +from config.database import Base + + +class Currency(Base): + __tablename__ = "currency" + + id = Column(Integer, primary_key=True, index=True) + code = Column(String(3), nullable=False, unique=True, index=True) + name = Column(String(128), nullable=False) + symbol = Column(String(8), nullable=True) + is_active = Column(Boolean, nullable=False, default=True) + + # reverse relationships (optional) + capex_items = relationship( + "Capex", back_populates="currency", lazy="select") + opex_items = relationship("Opex", back_populates="currency", lazy="select") + + def __repr__(self): + return f"" diff --git a/models/opex.py b/models/opex.py index 10c6308..a819864 100644 --- a/models/opex.py +++ b/models/opex.py @@ -1,3 +1,4 @@ +from sqlalchemy import event, text from sqlalchemy import Column, Integer, Float, String, ForeignKey from sqlalchemy.orm import relationship from config.database import Base @@ -10,12 +11,47 @@ class Opex(Base): scenario_id = Column(Integer, ForeignKey("scenario.id"), nullable=False) amount = Column(Float, nullable=False) description = Column(String, nullable=True) - currency_code = Column(String(3), nullable=False, default="USD") + currency_id = Column(Integer, ForeignKey("currency.id"), nullable=False) scenario = relationship("Scenario", back_populates="opex_items") + currency = relationship("Currency", back_populates="opex_items") def __repr__(self): return ( f"" + f"amount={self.amount} currency_id={self.currency_id}>" ) + + @property + def currency_code(self) -> str: + return self.currency.code if self.currency else None + + @currency_code.setter + def currency_code(self, value: str) -> None: + setattr(self, "_currency_code_pending", + (value or "USD").strip().upper()) + + +def _resolve_currency_opex(mapper, connection, target): + if getattr(target, "currency_id", None): + return + code = getattr(target, "_currency_code_pending", None) or "USD" + row = connection.execute(text("SELECT id FROM currency WHERE code = :code"), { + "code": code}).fetchone() + if row: + cid = row[0] + else: + res = connection.execute( + text("INSERT INTO currency (code, name, symbol, is_active) VALUES (:code, :name, :symbol, :active)"), + {"code": code, "name": code, "symbol": None, "active": True}, + ) + try: + cid = res.lastrowid + except Exception: + cid = connection.execute(text("SELECT id FROM currency WHERE code = :code"), { + "code": code}).scalar() + target.currency_id = cid + + +event.listen(Opex, "before_insert", _resolve_currency_opex) +event.listen(Opex, "before_update", _resolve_currency_opex) diff --git a/routes/costs.py b/routes/costs.py index d13beb9..4dafb96 100644 --- a/routes/costs.py +++ b/routes/costs.py @@ -16,7 +16,8 @@ class _CostBase(BaseModel): scenario_id: int amount: float description: Optional[str] = None - currency_code: str = "USD" + currency_code: Optional[str] = "USD" + currency_id: Optional[int] = None @field_validator("currency_code") @classmethod @@ -31,8 +32,12 @@ class CapexCreate(_CostBase): class CapexRead(_CostBase): id: int + # use from_attributes so Pydantic reads attributes off SQLAlchemy model model_config = ConfigDict(from_attributes=True) + # optionally include nested currency info + currency: Optional["CurrencyRead"] = None + class OpexCreate(_CostBase): pass @@ -41,12 +46,41 @@ class OpexCreate(_CostBase): class OpexRead(_CostBase): id: int model_config = ConfigDict(from_attributes=True) + currency: Optional["CurrencyRead"] = None + + +class CurrencyRead(BaseModel): + id: int + code: str + name: Optional[str] = None + symbol: Optional[str] = None + is_active: Optional[bool] = True + + model_config = ConfigDict(from_attributes=True) + + +# forward refs +CapexRead.model_rebuild() +OpexRead.model_rebuild() # Capex endpoints @router.post("/capex", response_model=CapexRead) def create_capex(item: CapexCreate, db: Session = Depends(get_db)): - db_item = Capex(**item.model_dump()) + payload = item.model_dump() + # Prefer explicit currency_id if supplied + cid = payload.get("currency_id") + if not cid: + code = (payload.pop("currency_code", "USD") or "USD").strip().upper() + currency_cls = __import__( + "models.currency", fromlist=["Currency"]).Currency + currency = db.query(currency_cls).filter_by(code=code).one_or_none() + if currency is None: + currency = currency_cls(code=code, name=code, symbol=None) + db.add(currency) + db.flush() + payload["currency_id"] = currency.id + db_item = Capex(**payload) db.add(db_item) db.commit() db.refresh(db_item) @@ -61,7 +95,19 @@ def list_capex(db: Session = Depends(get_db)): # Opex endpoints @router.post("/opex", response_model=OpexRead) def create_opex(item: OpexCreate, db: Session = Depends(get_db)): - db_item = Opex(**item.model_dump()) + payload = item.model_dump() + cid = payload.get("currency_id") + if not cid: + code = (payload.pop("currency_code", "USD") or "USD").strip().upper() + currency_cls = __import__( + "models.currency", fromlist=["Currency"]).Currency + currency = db.query(currency_cls).filter_by(code=code).one_or_none() + if currency is None: + currency = currency_cls(code=code, name=code, symbol=None) + db.add(currency) + db.flush() + payload["currency_id"] = currency.id + db_item = Opex(**payload) db.add(db_item) db.commit() db.refresh(db_item) diff --git a/routes/currencies.py b/routes/currencies.py new file mode 100644 index 0000000..06e6d48 --- /dev/null +++ b/routes/currencies.py @@ -0,0 +1,17 @@ +from typing import List, Dict, Any + +from fastapi import APIRouter, Depends +from sqlalchemy.orm import Session + +from models.currency import Currency +from routes.dependencies import get_db + +router = APIRouter(prefix="/api/currencies", tags=["Currencies"]) + + +@router.get("/", response_model=List[Dict[str, Any]]) +def list_currencies(db: Session = Depends(get_db)): + results = [] + for c in db.query(Currency).filter_by(is_active=True).order_by(Currency.code).all(): + results.append({"id": c.code, "name": f"{c.name} ({c.code})", "symbol": c.symbol}) + return results diff --git a/routes/ui.py b/routes/ui.py index e02c988..3ec8b37 100644 --- a/routes/ui.py +++ b/routes/ui.py @@ -18,11 +18,14 @@ from models.scenario import Scenario from models.simulation_result import SimulationResult from routes.dependencies import get_db from services.reporting import generate_report +from models.currency import Currency CURRENCY_CHOICES: list[Dict[str, Any]] = [ {"id": "USD", "name": "US Dollar (USD)"}, {"id": "EUR", "name": "Euro (EUR)"}, + {"id": "CLP", "name": "Chilean Peso (CLP)"}, + {"id": "RMB", "name": "Chinese Yuan (RMB)"}, {"id": "GBP", "name": "British Pound (GBP)"}, {"id": "CAD", "name": "Canadian Dollar (CAD)"}, {"id": "AUD", "name": "Australian Dollar (AUD)"}, @@ -140,6 +143,14 @@ def _load_costs(db: Session) -> Dict[str, Any]: } +def _load_currencies(db: Session) -> Dict[str, Any]: + items: list[Dict[str, Any]] = [] + for c in db.query(Currency).filter_by(is_active=True).order_by(Currency.code).all(): + items.append( + {"id": c.code, "name": f"{c.name} ({c.code})", "symbol": c.symbol}) + return {"currency_options": items} + + def _load_consumption(db: Session) -> Dict[str, Any]: grouped: defaultdict[int, list[Dict[str, Any]]] = defaultdict(list) for record in ( @@ -571,7 +582,7 @@ async def costs_view(request: Request, db: Session = Depends(get_db)): context: Dict[str, Any] = {} context.update(_load_scenarios(db)) context.update(_load_costs(db)) - context["currency_options"] = CURRENCY_CHOICES + context.update(_load_currencies(db)) return _render(request, "costs.html", context) diff --git a/scripts/backfill_currency.py b/scripts/backfill_currency.py new file mode 100644 index 0000000..4c4614b --- /dev/null +++ b/scripts/backfill_currency.py @@ -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() diff --git a/scripts/migrations/20251021_add_currency_and_unit_fields.sql b/scripts/migrations/20251021_add_currency_and_unit_fields.sql new file mode 100644 index 0000000..9c17d8d --- /dev/null +++ b/scripts/migrations/20251021_add_currency_and_unit_fields.sql @@ -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; diff --git a/scripts/migrations/20251022_create_currency_table_and_fks.sql b/scripts/migrations/20251022_create_currency_table_and_fks.sql new file mode 100644 index 0000000..2c31a40 --- /dev/null +++ b/scripts/migrations/20251022_create_currency_table_and_fks.sql @@ -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; diff --git a/static/js/costs.js b/static/js/costs.js index d0928cc..d75139c 100644 --- a/static/js/costs.js +++ b/static/js/costs.js @@ -41,6 +41,42 @@ document.addEventListener("DOMContentLoaded", () => { const capexCurrencySelect = document.getElementById("capex-form-currency"); const opexCurrencySelect = document.getElementById("opex-form-currency"); + // If no currency options were injected server-side, fetch from API + const fetchCurrencyOptions = async () => { + try { + const resp = await fetch("/api/currencies/"); + if (!resp.ok) return; + const list = await resp.json(); + if (Array.isArray(list) && list.length) { + currencyOptions = list; + populateCurrencySelects(); + } + } catch (err) { + console.warn("Unable to fetch currency options", err); + } + }; + + const populateCurrencySelects = () => { + const selectElements = [capexCurrencySelect, opexCurrencySelect].filter(Boolean); + selectElements.forEach((sel) => { + if (!sel) return; + // Clear non-empty options except the empty placeholder + const placeholder = sel.querySelector("option[value='']"); + sel.innerHTML = ""; + if (placeholder) sel.appendChild(placeholder); + currencyOptions.forEach((opt) => { + const option = document.createElement("option"); + option.value = opt.id; + option.textContent = opt.name || opt.id; + sel.appendChild(option); + }); + }); + }; + + // populate from injected options first, then fetch to refresh + if (currencyOptions && currencyOptions.length) populateCurrencySelects(); + else fetchCurrencyOptions(); + const showFeedback = (element, message, type = "success") => { if (!element) { return; diff --git a/tests/unit/test_currency_workflow.py b/tests/unit/test_currency_workflow.py new file mode 100644 index 0000000..72a4530 --- /dev/null +++ b/tests/unit/test_currency_workflow.py @@ -0,0 +1,54 @@ +from tests.unit.conftest import client + + +def test_create_capex_with_currency_code_and_list(): + # create scenario first (reuse helper from other tests) + from tests.unit.test_costs import _create_scenario + + sid = _create_scenario() + + # create with currency_code + payload = { + "scenario_id": sid, + "amount": 500.0, + "description": "Capex with GBP", + "currency_code": "GBP", + } + resp = client.post("/api/costs/capex", json=payload) + assert resp.status_code == 200 + data = resp.json() + assert data["currency_code"] == "GBP" or data.get( + "currency", {}).get("code") == "GBP" + + +def test_create_opex_with_currency_id(): + from tests.unit.test_costs import _create_scenario + from routes.currencies import list_currencies + + sid = _create_scenario() + + # fetch currencies to get an id + resp = client.get("/api/currencies/") + assert resp.status_code == 200 + currencies = resp.json() + assert len(currencies) > 0 + cid = currencies[0]["id"] + + payload = { + "scenario_id": sid, + "amount": 120.0, + "description": "Opex with explicit id", + "currency_id": cid, + } + resp = client.post("/api/costs/opex", json=payload) + assert resp.status_code == 200 + data = resp.json() + assert data["currency_id"] == cid + + +def test_list_currencies_endpoint(): + resp = client.get("/api/currencies/") + assert resp.status_code == 200 + data = resp.json() + assert isinstance(data, list) + assert all("id" in c and "code" in c for c in data) diff --git a/tests/unit/test_production.py b/tests/unit/test_production.py index 5d39151..cd7c851 100644 --- a/tests/unit/test_production.py +++ b/tests/unit/test_production.py @@ -21,7 +21,7 @@ def _create_scenario(client: TestClient) -> int: def test_create_production_record(client: TestClient) -> None: scenario_id = _create_scenario(client) - payload = { + payload: dict[str, any] = { "scenario_id": scenario_id, "amount": 475.25, "description": "Daily output",