feat(backend): refactor mono repository
This commit is contained in:
@@ -1,3 +0,0 @@
|
||||
# database/__init__.py
|
||||
from .connection import DatabaseConnection
|
||||
from .repository import Repository
|
||||
@@ -1,170 +0,0 @@
|
||||
# backend/database/connection.py
|
||||
"""
|
||||
Thin convenience layer over the builtin ``sqlite3`` module.
|
||||
|
||||
Why we need a wrapper
|
||||
---------------------
|
||||
* The repository (`repository.py`) expects the following public API:
|
||||
- ``execute`` – run an INSERT/UPDATE/DELETE.
|
||||
- ``fetchone`` / ``fetchall`` – run a SELECT and get the result(s).
|
||||
- ``lastrowid`` – primary‑key of the most recent INSERT.
|
||||
- ``close`` – close the DB connection.
|
||||
* A wrapper lets us:
|
||||
• Set a sensible ``row_factory`` (``sqlite3.Row``) so column names are
|
||||
accessible as ``row["ColumnName"]``.
|
||||
• Centralise ``commit``/``rollback`` handling.
|
||||
• Provide type hints and a context‑manager interface
|
||||
(``with DatabaseConnection(...):``) which is handy for tests.
|
||||
* No external dependencies – everything stays pure‑Python/SQLite.
|
||||
|
||||
The implementation below is deliberately tiny: it only does what the
|
||||
application needs while remaining easy to extend later (e.g. add
|
||||
connection‑pooling or logging).
|
||||
"""
|
||||
|
||||
from __future__ import annotations
|
||||
|
||||
import sqlite3
|
||||
from pathlib import Path
|
||||
from typing import Any, Iterable, Tuple, List, Optional, Union
|
||||
|
||||
|
||||
class DatabaseConnection:
|
||||
"""
|
||||
Simple wrapper around a SQLite connection.
|
||||
|
||||
Core behaviour
|
||||
---------------
|
||||
* ``row_factory`` is set to :class:`sqlite3.Row` – callers can use
|
||||
``row["col_name"]`` or treat the row like a mapping.
|
||||
* All ``execute`` calls are automatically committed.
|
||||
If an exception bubbles out, the transaction is rolled back.
|
||||
* ``execute`` returns the cursor so callers can chain
|
||||
``cursor.lastrowid`` if they need the autogenerated PK.
|
||||
* Implements the context‑manager protocol (``with ... as db:``).
|
||||
|
||||
The public API matches what ``Repository`` expects:
|
||||
- execute(sql, params=None) → None
|
||||
- fetchone(sql, params=None) → Optional[sqlite3.Row]
|
||||
- fetchall(sql, params=None) → List[sqlite3.Row]
|
||||
- lastrowid → int
|
||||
- close()
|
||||
"""
|
||||
|
||||
# -----------------------------------------------------------------
|
||||
# Construction / context‑manager protocol
|
||||
# -----------------------------------------------------------------
|
||||
def __init__(
|
||||
self,
|
||||
db_path: Union[str, Path],
|
||||
*,
|
||||
timeout: float = 5.0,
|
||||
detect_types: int = sqlite3.PARSE_DECLTYPES | sqlite3.PARSE_COLNAMES,
|
||||
) -> None:
|
||||
"""
|
||||
Parameters
|
||||
----------
|
||||
db_path
|
||||
Path to the SQLite file. ``":memory:"`` works for tests.
|
||||
timeout
|
||||
Seconds to wait for a lock before raising ``sqlite3.OperationalError``.
|
||||
detect_types
|
||||
Enable type conversion (so DATE/DATETIME are returned as ``datetime``).
|
||||
"""
|
||||
self._conn: sqlite3.Connection = sqlite3.connect(
|
||||
str(db_path), timeout=timeout, detect_types=detect_types
|
||||
)
|
||||
# ``Row`` makes column access dictionary‑like and preserves order.
|
||||
self._conn.row_factory = sqlite3.Row
|
||||
self._cursor: sqlite3.Cursor = self._conn.cursor()
|
||||
|
||||
def __enter__(self) -> "DatabaseConnection":
|
||||
"""Allow ``with DatabaseConnection(...) as db:`` usage."""
|
||||
return self
|
||||
|
||||
def __exit__(self, exc_type, exc_val, exc_tb) -> Optional[bool]:
|
||||
"""
|
||||
On normal exit commit the transaction, otherwise roll back.
|
||||
Returning ``False`` propagates any exception.
|
||||
"""
|
||||
if exc_type is None:
|
||||
try:
|
||||
self._conn.commit()
|
||||
finally:
|
||||
self.close()
|
||||
else:
|
||||
# Something went wrong – roll back to keep the DB clean.
|
||||
self._conn.rollback()
|
||||
self.close()
|
||||
# ``None`` means “don’t suppress exceptions”
|
||||
return None
|
||||
|
||||
# -----------------------------------------------------------------
|
||||
# Low‑level helpers used by the repository
|
||||
# -----------------------------------------------------------------
|
||||
@property
|
||||
def cursor(self) -> sqlite3.Cursor:
|
||||
"""Expose the underlying cursor – rarely needed outside the repo."""
|
||||
return self._cursor
|
||||
|
||||
@property
|
||||
def lastrowid(self) -> int:
|
||||
"""PK of the most recent ``INSERT`` executed on this connection."""
|
||||
return self._cursor.lastrowid
|
||||
|
||||
# -----------------------------------------------------------------
|
||||
# Public API – the four methods used throughout the code base
|
||||
# -----------------------------------------------------------------
|
||||
def execute(self, sql: str, params: Optional[Tuple[Any, ...]] = None) -> None:
|
||||
"""
|
||||
Run an INSERT/UPDATE/DELETE statement and commit immediately.
|
||||
|
||||
``params`` may be ``None`` (no placeholders) or a tuple of values.
|
||||
"""
|
||||
try:
|
||||
if params is None:
|
||||
self._cursor.execute(sql)
|
||||
else:
|
||||
self._cursor.execute(sql, params)
|
||||
self._conn.commit()
|
||||
except Exception:
|
||||
# Ensure we don’t leave the connection in a half‑committed state.
|
||||
self._conn.rollback()
|
||||
raise
|
||||
|
||||
def fetchone(
|
||||
self, sql: str, params: Optional[Tuple[Any, ...]] = None
|
||||
) -> Optional[sqlite3.Row]:
|
||||
"""
|
||||
Execute a SELECT that returns at most one row.
|
||||
|
||||
Returns ``None`` when the result set is empty.
|
||||
"""
|
||||
if params is None:
|
||||
self._cursor.execute(sql)
|
||||
else:
|
||||
self._cursor.execute(sql, params)
|
||||
return self._cursor.fetchone()
|
||||
|
||||
def fetchall(
|
||||
self, sql: str, params: Optional[Tuple[Any, ...]] = None
|
||||
) -> List[sqlite3.Row]:
|
||||
"""
|
||||
Execute a SELECT and return **all** rows as a list.
|
||||
|
||||
The rows are ``sqlite3.Row`` instances, which behave like dicts.
|
||||
"""
|
||||
if params is None:
|
||||
self._cursor.execute(sql)
|
||||
else:
|
||||
self._cursor.execute(sql, params)
|
||||
return self._cursor.fetchall()
|
||||
|
||||
def close(self) -> None:
|
||||
"""Close the underlying SQLite connection."""
|
||||
# ``cursor`` is automatically closed when the connection closes,
|
||||
# but we explicitly close it for clarity.
|
||||
try:
|
||||
self._cursor.close()
|
||||
finally:
|
||||
self._conn.close()
|
||||
@@ -1,22 +0,0 @@
|
||||
# backend/database/models/__init__.py
|
||||
from .classification import Classification
|
||||
from .member import Member
|
||||
from .servicetype import ServiceType
|
||||
from .service import Service
|
||||
from .serviceavailability import ServiceAvailability
|
||||
from .schedule import Schedule
|
||||
from .acceptedlog import AcceptedLog
|
||||
from .declinelog import DeclineLog
|
||||
from .scheduledlog import ScheduledLog
|
||||
|
||||
__all__ = [
|
||||
"Classification",
|
||||
"Member",
|
||||
"ServiceType",
|
||||
"Service",
|
||||
"ServiceAvailability",
|
||||
"Schedule",
|
||||
"AcceptedLog",
|
||||
"DeclineLog",
|
||||
"ScheduledLog",
|
||||
]
|
||||
@@ -1,49 +0,0 @@
|
||||
from __future__ import annotations
|
||||
from dataclasses import dataclass, asdict, fields
|
||||
from datetime import date, datetime
|
||||
from typing import Any, Dict, Tuple, Type, TypeVar, Union
|
||||
|
||||
Row = Tuple[Any, ...] | Dict[str, Any] # what sqlite3.Row returns
|
||||
|
||||
T = TypeVar("T", bound="BaseModel")
|
||||
|
||||
|
||||
@dataclass()
|
||||
class BaseModel:
|
||||
"""A tiny helper that gives every model a common interface."""
|
||||
|
||||
@classmethod
|
||||
def from_row(cls: Type[T], row: Row) -> T:
|
||||
"""
|
||||
Build a model instance from a sqlite3.Row (or a dict‑like object).
|
||||
Column names are matched to the dataclass field names.
|
||||
"""
|
||||
if isinstance(row, dict):
|
||||
data = row
|
||||
else: # sqlite3.Row behaves like a mapping, but we guard for safety
|
||||
data = dict(row)
|
||||
|
||||
# Convert raw strings to proper Python types where we know the annotation
|
||||
converted: Dict[str, Any] = {}
|
||||
for f in fields(cls):
|
||||
value = data.get(f.name)
|
||||
if value is None:
|
||||
converted[f.name] = None
|
||||
continue
|
||||
|
||||
# datetime/date handling – sqlite returns str in ISO format
|
||||
if f.type is datetime:
|
||||
converted[f.name] = datetime.fromisoformat(value)
|
||||
elif f.type is date:
|
||||
converted[f.name] = date.fromisoformat(value)
|
||||
else:
|
||||
converted[f.name] = value
|
||||
return cls(**converted) # type: ignore[arg-type]
|
||||
|
||||
def to_dict(self) -> Dict[str, Any]:
|
||||
"""Return a plain dict (useful for INSERT/UPDATE statements)."""
|
||||
return asdict(self)
|
||||
|
||||
def __repr__(self) -> str: # a nicer representation when printing
|
||||
field_vals = ", ".join(f"{f.name}={getattr(self, f.name)!r}" for f in fields(self))
|
||||
return f"{self.__class__.__name__}({field_vals})"
|
||||
@@ -1,11 +0,0 @@
|
||||
from dataclasses import dataclass
|
||||
from datetime import datetime
|
||||
from ._base import BaseModel
|
||||
|
||||
|
||||
@dataclass()
|
||||
class AcceptedLog(BaseModel):
|
||||
LogId: int
|
||||
MemberId: int
|
||||
ServiceId: int
|
||||
AcceptedAt: datetime
|
||||
@@ -1,8 +0,0 @@
|
||||
from dataclasses import dataclass
|
||||
from ._base import BaseModel
|
||||
|
||||
|
||||
@dataclass()
|
||||
class Classification(BaseModel):
|
||||
ClassificationId: int
|
||||
ClassificationName: str
|
||||
@@ -1,14 +0,0 @@
|
||||
from dataclasses import dataclass
|
||||
from datetime import datetime, date
|
||||
from typing import Optional
|
||||
from ._base import BaseModel
|
||||
|
||||
|
||||
@dataclass()
|
||||
class DeclineLog(BaseModel):
|
||||
DeclineId: int
|
||||
MemberId: int
|
||||
ServiceId: int
|
||||
DeclinedAt: datetime
|
||||
DeclineDate: date # the service day that was declined
|
||||
Reason: Optional[str] = None
|
||||
@@ -1,20 +0,0 @@
|
||||
from dataclasses import dataclass
|
||||
from datetime import datetime, date
|
||||
from typing import Optional
|
||||
from ._base import BaseModel
|
||||
|
||||
|
||||
@dataclass
|
||||
class Member(BaseModel):
|
||||
MemberId: int
|
||||
FirstName: str
|
||||
LastName: str
|
||||
Email: Optional[str] = None
|
||||
PhoneNumber: Optional[str] = None
|
||||
ClassificationId: Optional[int] = None
|
||||
Notes: Optional[str] = None
|
||||
IsActive: int = 1
|
||||
LastScheduledAt: Optional[datetime] = None
|
||||
LastAcceptedAt: Optional[datetime] = None
|
||||
LastDeclinedAt: Optional[datetime] = None
|
||||
DeclineStreak: int = 0
|
||||
@@ -1,17 +0,0 @@
|
||||
from dataclasses import dataclass
|
||||
from datetime import datetime
|
||||
from typing import Optional
|
||||
from ._base import BaseModel
|
||||
|
||||
|
||||
@dataclass
|
||||
class Schedule(BaseModel):
|
||||
ScheduleId: int
|
||||
ServiceId: int
|
||||
MemberId: int
|
||||
Status: str # 'pending' | 'accepted' | 'declined'
|
||||
ScheduledAt: datetime # renamed from OfferedAt
|
||||
AcceptedAt: Optional[datetime] = None
|
||||
DeclinedAt: Optional[datetime] = None
|
||||
ExpiresAt: Optional[datetime] = None
|
||||
DeclineReason: Optional[str] = None
|
||||
@@ -1,12 +0,0 @@
|
||||
from dataclasses import dataclass
|
||||
from datetime import datetime
|
||||
from ._base import BaseModel
|
||||
|
||||
|
||||
@dataclass()
|
||||
class ScheduledLog(BaseModel):
|
||||
LogId: int
|
||||
MemberId: int
|
||||
ServiceId: int
|
||||
ScheduledAt: datetime
|
||||
ExpiresAt: datetime
|
||||
@@ -1,10 +0,0 @@
|
||||
from dataclasses import dataclass
|
||||
from datetime import date
|
||||
from ._base import BaseModel
|
||||
|
||||
|
||||
@dataclass()
|
||||
class Service(BaseModel):
|
||||
ServiceId: int
|
||||
ServiceTypeId: int
|
||||
ServiceDate: date
|
||||
@@ -1,9 +0,0 @@
|
||||
from dataclasses import dataclass
|
||||
from ._base import BaseModel
|
||||
|
||||
|
||||
@dataclass()
|
||||
class ServiceAvailability(BaseModel):
|
||||
ServiceAvailabilityId: int
|
||||
MemberId: int
|
||||
ServiceTypeId: int
|
||||
@@ -1,8 +0,0 @@
|
||||
from dataclasses import dataclass
|
||||
from ._base import BaseModel
|
||||
|
||||
|
||||
@dataclass()
|
||||
class ServiceType(BaseModel):
|
||||
ServiceTypeId: int
|
||||
TypeName: str
|
||||
@@ -1,130 +0,0 @@
|
||||
-- ==============================================================
|
||||
-- SQLite schema for the scheduling system
|
||||
-- * round‑robin queue is driven by Members.LastAcceptedAt
|
||||
-- * one‑day cool‑off is driven by Members.LastDeclinedAt (DATE)
|
||||
-- * reservations are stored in Schedules (Status = 'pending' | 'accepted' | 'declined')
|
||||
-- * audit tables: AcceptedLog, DeclineLog, ScheduledLog
|
||||
-- ==============================================================
|
||||
|
||||
PRAGMA foreign_keys = ON;
|
||||
|
||||
-- -----------------------------------------------------------------
|
||||
-- 1. Core lookup tables
|
||||
-- -----------------------------------------------------------------
|
||||
CREATE TABLE Classifications (
|
||||
ClassificationId INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
ClassificationName TEXT NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
CREATE TABLE ServiceTypes (
|
||||
ServiceTypeId INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
TypeName TEXT NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
-- -----------------------------------------------------------------
|
||||
-- 2. Members – stores round‑robin timestamps and cool‑off date
|
||||
-- -----------------------------------------------------------------
|
||||
CREATE TABLE Members (
|
||||
MemberId INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
FirstName TEXT NOT NULL,
|
||||
LastName TEXT NOT NULL,
|
||||
Email TEXT UNIQUE,
|
||||
PhoneNumber TEXT,
|
||||
ClassificationId INTEGER,
|
||||
Notes TEXT,
|
||||
IsActive INTEGER DEFAULT 1 CHECK (IsActive IN (0,1)),
|
||||
|
||||
-- Queue‑related columns -------------------------------------------------
|
||||
LastScheduledAt DATETIME, -- set when a position is SCHEDULED
|
||||
LastAcceptedAt DATETIME, -- set when a position is ACCEPTED
|
||||
LastDeclinedAt DATETIME, -- set the time a member last DECLINED
|
||||
DeclineStreak INTEGER DEFAULT 0,
|
||||
-------------------------------------------------------------------------
|
||||
|
||||
FOREIGN KEY (ClassificationId) REFERENCES Classifications(ClassificationId)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_members_queue
|
||||
ON Members (ClassificationId, IsActive,
|
||||
LastDeclinedAt, LastAcceptedAt, LastScheduledAt);
|
||||
|
||||
|
||||
-- -----------------------------------------------------------------
|
||||
-- 3. Services – a concrete service on a given date
|
||||
-- -----------------------------------------------------------------
|
||||
CREATE TABLE Services (
|
||||
ServiceId INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
ServiceTypeId INTEGER NOT NULL,
|
||||
ServiceDate DATE NOT NULL,
|
||||
FOREIGN KEY (ServiceTypeId) REFERENCES ServiceTypes(ServiceTypeId)
|
||||
);
|
||||
|
||||
-- -----------------------------------------------------------------
|
||||
-- 4. ServiceAvailability – which members are eligible for which service types
|
||||
-- -----------------------------------------------------------------
|
||||
CREATE TABLE ServiceAvailability (
|
||||
ServiceAvailabilityId INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
MemberId INTEGER NOT NULL,
|
||||
ServiceTypeId INTEGER NOT NULL,
|
||||
UNIQUE (MemberId, ServiceTypeId),
|
||||
FOREIGN KEY (MemberId) REFERENCES Members(MemberId),
|
||||
FOREIGN KEY (ServiceTypeId) REFERENCES ServiceTypes(ServiceTypeId)
|
||||
);
|
||||
|
||||
-- -----------------------------------------------------------------
|
||||
-- 5. Schedules – also acts as the reservation/lock table
|
||||
-- -----------------------------------------------------------------
|
||||
CREATE TABLE Schedules (
|
||||
ScheduleId INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
ServiceId INTEGER NOT NULL,
|
||||
MemberId INTEGER NOT NULL,
|
||||
|
||||
-- Reservation / status columns -----------------------------------------
|
||||
Status TEXT NOT NULL CHECK (Status IN ('pending','accepted','declined')),
|
||||
ScheduledAt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, -- renamed from OfferedAt
|
||||
AcceptedAt DATETIME, -- set when status -> 'accepted'
|
||||
DeclinedAt DATETIME, -- set when status -> 'declined'
|
||||
ExpiresAt DATETIME, -- pending rows expire after X minutes
|
||||
DeclineReason TEXT,
|
||||
-------------------------------------------------------------------------
|
||||
|
||||
UNIQUE (ServiceId, MemberId), -- one row per member per service
|
||||
FOREIGN KEY (MemberId) REFERENCES Members(MemberId),
|
||||
FOREIGN KEY (ServiceId) REFERENCES Services(ServiceId)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_sched_member_service_status
|
||||
ON Schedules(MemberId, ServiceId, Status);
|
||||
|
||||
-- -----------------------------------------------------------------
|
||||
-- 6. Audit tables
|
||||
-- -----------------------------------------------------------------
|
||||
CREATE TABLE AcceptedLog (
|
||||
LogId INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
MemberId INTEGER NOT NULL,
|
||||
ServiceId INTEGER NOT NULL,
|
||||
AcceptedAt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
FOREIGN KEY (MemberId) REFERENCES Members(MemberId),
|
||||
FOREIGN KEY (ServiceId) REFERENCES Services(ServiceId)
|
||||
);
|
||||
|
||||
CREATE TABLE DeclineLog (
|
||||
DeclineId INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
MemberId INTEGER NOT NULL,
|
||||
ServiceId INTEGER NOT NULL,
|
||||
DeclinedAt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
DeclineDate DATE NOT NULL, -- the service day that was declined
|
||||
Reason TEXT,
|
||||
FOREIGN KEY (MemberId) REFERENCES Members(MemberId),
|
||||
FOREIGN KEY (ServiceId) REFERENCES Services(ServiceId)
|
||||
);
|
||||
|
||||
CREATE TABLE ScheduledLog (
|
||||
LogId INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
MemberId INTEGER NOT NULL,
|
||||
ServiceId INTEGER NOT NULL,
|
||||
ScheduledAt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
ExpiresAt DATETIME,
|
||||
FOREIGN KEY (MemberId) REFERENCES Members(MemberId),
|
||||
FOREIGN KEY (ServiceId) REFERENCES Services(ServiceId)
|
||||
);
|
||||
Reference in New Issue
Block a user