/** * SQLite Database Wrapper for BraceFlow DEV * Mirrors the MySQL schema but uses SQLite for local development */ import Database from 'better-sqlite3'; import path from 'path'; import { fileURLToPath } from 'url'; const __dirname = path.dirname(fileURLToPath(import.meta.url)); // Use DB_PATH from env (Docker) or local path (dev) const DB_PATH = process.env.DB_PATH || path.join(__dirname, '..', 'braceflow_DEV.db'); console.log(`Database path: ${DB_PATH}`); // Initialize database const db = new Database(DB_PATH); db.pragma('journal_mode = WAL'); // Create tables db.exec(` -- Main cases table CREATE TABLE IF NOT EXISTS brace_cases ( case_id TEXT PRIMARY KEY, case_type TEXT NOT NULL DEFAULT 'braceflow', status TEXT NOT NULL DEFAULT 'created' CHECK(status IN ( 'created', 'running', 'completed', 'failed', 'cancelled', 'processing_brace', 'brace_generated', 'brace_failed', 'landmarks_detected', 'landmarks_approved', 'analysis_complete', 'body_scan_uploaded' )), current_step TEXT DEFAULT NULL, execution_arn TEXT DEFAULT NULL, notes TEXT DEFAULT NULL, analysis_result TEXT DEFAULT NULL, landmarks_data TEXT DEFAULT NULL, analysis_data TEXT DEFAULT NULL, markers_data TEXT DEFAULT NULL, body_scan_path TEXT DEFAULT NULL, body_scan_url TEXT DEFAULT NULL, body_scan_metadata TEXT DEFAULT NULL, created_by INTEGER DEFAULT NULL, created_at TEXT NOT NULL DEFAULT (datetime('now')), updated_at TEXT NOT NULL DEFAULT (datetime('now')) ); -- Case steps table CREATE TABLE IF NOT EXISTS brace_case_steps ( case_id TEXT NOT NULL, step_name TEXT NOT NULL, step_order INTEGER NOT NULL, status TEXT NOT NULL DEFAULT 'pending' CHECK(status IN ( 'pending', 'running', 'done', 'failed', 'waiting_for_landmarks' )), error_message TEXT DEFAULT NULL, started_at TEXT DEFAULT NULL, finished_at TEXT DEFAULT NULL, created_at TEXT NOT NULL DEFAULT (datetime('now')), updated_at TEXT NOT NULL DEFAULT (datetime('now')), PRIMARY KEY (case_id, step_name), FOREIGN KEY (case_id) REFERENCES brace_cases(case_id) ON DELETE CASCADE ); -- Task tokens table (for pipeline state) CREATE TABLE IF NOT EXISTS brace_case_task_tokens ( case_id TEXT NOT NULL, step_name TEXT NOT NULL, task_token TEXT NOT NULL, status TEXT NOT NULL DEFAULT 'active' CHECK(status IN ('active', 'consumed', 'expired')), created_at TEXT NOT NULL DEFAULT (datetime('now')), updated_at TEXT NOT NULL DEFAULT (datetime('now')), PRIMARY KEY (case_id, step_name), FOREIGN KEY (case_id) REFERENCES brace_cases(case_id) ON DELETE CASCADE ); -- Users table (for authentication) CREATE TABLE IF NOT EXISTS users ( id INTEGER PRIMARY KEY AUTOINCREMENT, username TEXT NOT NULL UNIQUE, password_hash TEXT NOT NULL, email TEXT DEFAULT NULL, full_name TEXT DEFAULT NULL, role TEXT NOT NULL DEFAULT 'user' CHECK(role IN ('admin', 'user', 'viewer')), is_active INTEGER NOT NULL DEFAULT 1, last_login TEXT DEFAULT NULL, created_at TEXT NOT NULL DEFAULT (datetime('now')), updated_at TEXT NOT NULL DEFAULT (datetime('now')) ); -- User sessions table (for token management) CREATE TABLE IF NOT EXISTS user_sessions ( id INTEGER PRIMARY KEY AUTOINCREMENT, user_id INTEGER NOT NULL, session_token TEXT NOT NULL UNIQUE, expires_at TEXT NOT NULL, created_at TEXT NOT NULL DEFAULT (datetime('now')), FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ); -- Audit log table (for tracking admin actions) CREATE TABLE IF NOT EXISTS audit_log ( id INTEGER PRIMARY KEY AUTOINCREMENT, user_id INTEGER DEFAULT NULL, action TEXT NOT NULL, entity_type TEXT NOT NULL, entity_id TEXT DEFAULT NULL, details TEXT DEFAULT NULL, ip_address TEXT DEFAULT NULL, created_at TEXT NOT NULL DEFAULT (datetime('now')), FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE SET NULL ); -- Create indexes CREATE INDEX IF NOT EXISTS idx_cases_status ON brace_cases(status); CREATE INDEX IF NOT EXISTS idx_cases_created ON brace_cases(created_at); CREATE INDEX IF NOT EXISTS idx_steps_case_id ON brace_case_steps(case_id); CREATE INDEX IF NOT EXISTS idx_users_username ON users(username); CREATE INDEX IF NOT EXISTS idx_users_role ON users(role); CREATE INDEX IF NOT EXISTS idx_sessions_token ON user_sessions(session_token); CREATE INDEX IF NOT EXISTS idx_sessions_user ON user_sessions(user_id); CREATE INDEX IF NOT EXISTS idx_audit_user ON audit_log(user_id); CREATE INDEX IF NOT EXISTS idx_audit_action ON audit_log(action); CREATE INDEX IF NOT EXISTS idx_audit_created ON audit_log(created_at); `); // Migration: Add new columns to existing tables try { db.exec(`ALTER TABLE brace_cases ADD COLUMN analysis_data TEXT DEFAULT NULL`); } catch (e) { /* Column already exists */ } try { db.exec(`ALTER TABLE brace_cases ADD COLUMN body_scan_path TEXT DEFAULT NULL`); } catch (e) { /* Column already exists */ } try { db.exec(`ALTER TABLE brace_cases ADD COLUMN body_scan_url TEXT DEFAULT NULL`); } catch (e) { /* Column already exists */ } try { db.exec(`ALTER TABLE brace_cases ADD COLUMN body_scan_metadata TEXT DEFAULT NULL`); } catch (e) { /* Column already exists */ } try { db.exec(`ALTER TABLE brace_cases ADD COLUMN created_by INTEGER DEFAULT NULL`); } catch (e) { /* Column already exists */ } // Insert default admin user if not exists (password: admin123) // Note: In production, use proper bcrypt hashing. This is a simple hash for dev. try { const existingAdmin = db.prepare(`SELECT id FROM users WHERE username = ?`).get('admin'); if (!existingAdmin) { // Simple hash for dev - in production use bcrypt db.prepare(` INSERT INTO users (username, password_hash, full_name, role, is_active) VALUES (?, ?, ?, ?, ?) `).run('admin', 'admin123', 'Administrator', 'admin', 1); console.log('Created default admin user (admin/admin123)'); } } catch (e) { /* User already exists or table not ready */ } // Step names for the pipeline const STEP_NAMES = [ 'LandmarkDetection', 'LandmarkApproval', 'SpineAnalysis', 'BodyScanUpload', 'BraceGeneration', 'BraceApproval' ]; /** * Create a new case */ export function createCase(caseId, caseType = 'braceflow', notes = null) { const insertCase = db.prepare(` INSERT INTO brace_cases (case_id, case_type, status, notes, created_at, updated_at) VALUES (?, ?, 'created', ?, datetime('now'), datetime('now')) `); const insertStep = db.prepare(` INSERT INTO brace_case_steps (case_id, step_name, step_order, status, created_at, updated_at) VALUES (?, ?, ?, 'pending', datetime('now'), datetime('now')) `); const transaction = db.transaction(() => { insertCase.run(caseId, caseType, notes); STEP_NAMES.forEach((stepName, idx) => { insertStep.run(caseId, stepName, idx + 1); }); }); transaction(); return { caseId, status: 'created', steps: STEP_NAMES }; } /** * List all cases */ export function listCases() { const stmt = db.prepare(` SELECT case_id as caseId, case_type, status, current_step, notes, analysis_result, landmarks_data, created_at, updated_at FROM brace_cases ORDER BY created_at DESC `); return stmt.all(); } /** * Get case by ID with steps */ export function getCase(caseId) { const caseStmt = db.prepare(` SELECT case_id, case_type, status, current_step, notes, analysis_result, landmarks_data, analysis_data, markers_data, body_scan_path, body_scan_url, body_scan_metadata, created_at, updated_at FROM brace_cases WHERE case_id = ? `); const stepsStmt = db.prepare(` SELECT step_name, step_order, status, error_message, started_at, finished_at FROM brace_case_steps WHERE case_id = ? ORDER BY step_order ASC `); const caseData = caseStmt.get(caseId); if (!caseData) return null; const steps = stepsStmt.all(caseId); // Parse JSON fields let analysisResult = null; let landmarksData = null; let analysisData = null; let markersData = null; let bodyScanMetadata = null; try { if (caseData.analysis_result) { analysisResult = JSON.parse(caseData.analysis_result); } } catch (e) { /* ignore */ } try { if (caseData.landmarks_data) { landmarksData = JSON.parse(caseData.landmarks_data); } } catch (e) { /* ignore */ } try { if (caseData.analysis_data) { analysisData = JSON.parse(caseData.analysis_data); } } catch (e) { /* ignore */ } try { if (caseData.markers_data) { markersData = JSON.parse(caseData.markers_data); } } catch (e) { /* ignore */ } try { if (caseData.body_scan_metadata) { bodyScanMetadata = JSON.parse(caseData.body_scan_metadata); } } catch (e) { /* ignore */ } return { caseId: caseData.case_id, case_type: caseData.case_type, status: caseData.status, current_step: caseData.current_step, notes: caseData.notes, analysis_result: analysisResult, landmarks_data: landmarksData, analysis_data: analysisData, markers_data: markersData, body_scan_path: caseData.body_scan_path, body_scan_url: caseData.body_scan_url, body_scan_metadata: bodyScanMetadata, created_at: caseData.created_at, updated_at: caseData.updated_at, steps }; } /** * Update case status */ export function updateCaseStatus(caseId, status, currentStep = null) { const stmt = db.prepare(` UPDATE brace_cases SET status = ?, current_step = ?, updated_at = datetime('now') WHERE case_id = ? `); return stmt.run(status, currentStep, caseId); } /** * Save landmarks data */ export function saveLandmarks(caseId, landmarksData) { const stmt = db.prepare(` UPDATE brace_cases SET landmarks_data = ?, status = 'landmarks_detected', current_step = 'LandmarkApproval', updated_at = datetime('now') WHERE case_id = ? `); return stmt.run(JSON.stringify(landmarksData), caseId); } /** * Approve landmarks */ export function approveLandmarks(caseId, updatedLandmarks = null) { const stmt = db.prepare(` UPDATE brace_cases SET landmarks_data = COALESCE(?, landmarks_data), status = 'landmarks_approved', current_step = 'SpineAnalysis', updated_at = datetime('now') WHERE case_id = ? `); const data = updatedLandmarks ? JSON.stringify(updatedLandmarks) : null; return stmt.run(data, caseId); } /** * Save analysis result */ export function saveAnalysisResult(caseId, analysisResult) { const stmt = db.prepare(` UPDATE brace_cases SET analysis_result = ?, status = 'analysis_complete', current_step = 'BraceGeneration', updated_at = datetime('now') WHERE case_id = ? `); return stmt.run(JSON.stringify(analysisResult), caseId); } /** * Save brace generation result */ export function saveBraceResult(caseId, braceResult) { const currentData = getCase(caseId); const updatedAnalysis = { ...(currentData?.analysis_result || {}), brace: braceResult }; const stmt = db.prepare(` UPDATE brace_cases SET analysis_result = ?, status = 'brace_generated', current_step = 'BraceApproval', updated_at = datetime('now') WHERE case_id = ? `); return stmt.run(JSON.stringify(updatedAnalysis), caseId); } /** * Save both braces generation result (regular + vase) */ export function saveBothBracesResult(caseId, bracesData) { const currentData = getCase(caseId); const updatedAnalysis = { ...(currentData?.analysis_result || {}), braces: bracesData.braces, rigoType: bracesData.rigoType, cobbAngles: bracesData.cobbAngles, bodyScanUsed: bracesData.bodyScanUsed }; const stmt = db.prepare(` UPDATE brace_cases SET analysis_result = ?, status = 'brace_generated', current_step = 'BraceApproval', updated_at = datetime('now') WHERE case_id = ? `); return stmt.run(JSON.stringify(updatedAnalysis), caseId); } /** * Save markers data (for brace editor) */ export function saveMarkers(caseId, markersData) { const stmt = db.prepare(` UPDATE brace_cases SET markers_data = ?, updated_at = datetime('now') WHERE case_id = ? `); return stmt.run(JSON.stringify(markersData), caseId); } /** * Save analysis data (from recalculate - separate from brace result) */ export function saveAnalysisData(caseId, analysisData) { const stmt = db.prepare(` UPDATE brace_cases SET analysis_data = ?, updated_at = datetime('now') WHERE case_id = ? `); return stmt.run(JSON.stringify(analysisData), caseId); } /** * Save body scan info * Note: We use 'analysis_complete' status for compatibility with existing databases * that may not have 'body_scan_uploaded' in their CHECK constraint */ export function saveBodyScan(caseId, scanPath, scanUrl, metadata = null) { const stmt = db.prepare(` UPDATE brace_cases SET body_scan_path = ?, body_scan_url = ?, body_scan_metadata = ?, status = 'analysis_complete', current_step = 'BraceGeneration', updated_at = datetime('now') WHERE case_id = ? `); const metadataJson = metadata ? JSON.stringify(metadata) : null; return stmt.run(scanPath, scanUrl, metadataJson, caseId); } /** * Clear body scan (user wants to skip or remove) */ export function clearBodyScan(caseId) { const stmt = db.prepare(` UPDATE brace_cases SET body_scan_path = NULL, body_scan_url = NULL, body_scan_metadata = NULL, updated_at = datetime('now') WHERE case_id = ? `); return stmt.run(caseId); } /** * Delete case */ export function deleteCase(caseId) { const stmt = db.prepare(`DELETE FROM brace_cases WHERE case_id = ?`); return stmt.run(caseId); } /** * Update step status */ export function updateStepStatus(caseId, stepName, status, errorMessage = null) { const stmt = db.prepare(` UPDATE brace_case_steps SET status = ?, error_message = ?, started_at = CASE WHEN ? = 'running' THEN datetime('now') ELSE started_at END, finished_at = CASE WHEN ? IN ('done', 'failed') THEN datetime('now') ELSE finished_at END, updated_at = datetime('now') WHERE case_id = ? AND step_name = ? `); return stmt.run(status, errorMessage, status, status, caseId, stepName); } // ============================================ // USER MANAGEMENT // ============================================ /** * Get user by username (for login) */ export function getUserByUsername(username) { const stmt = db.prepare(` SELECT id, username, password_hash, email, full_name, role, is_active, last_login, created_at FROM users WHERE username = ? `); return stmt.get(username); } /** * Get user by ID */ export function getUserById(userId) { const stmt = db.prepare(` SELECT id, username, email, full_name, role, is_active, last_login, created_at, updated_at FROM users WHERE id = ? `); return stmt.get(userId); } /** * List all users */ export function listUsers() { const stmt = db.prepare(` SELECT id, username, email, full_name, role, is_active, last_login, created_at, updated_at FROM users ORDER BY created_at DESC `); return stmt.all(); } /** * Create user */ export function createUser(username, passwordHash, email = null, fullName = null, role = 'user') { const stmt = db.prepare(` INSERT INTO users (username, password_hash, email, full_name, role, is_active, created_at, updated_at) VALUES (?, ?, ?, ?, ?, 1, datetime('now'), datetime('now')) `); const result = stmt.run(username, passwordHash, email, fullName, role); return { id: result.lastInsertRowid, username, email, fullName, role }; } /** * Update user */ export function updateUser(userId, updates) { const fields = []; const values = []; if (updates.email !== undefined) { fields.push('email = ?'); values.push(updates.email); } if (updates.fullName !== undefined) { fields.push('full_name = ?'); values.push(updates.fullName); } if (updates.role !== undefined) { fields.push('role = ?'); values.push(updates.role); } if (updates.isActive !== undefined) { fields.push('is_active = ?'); values.push(updates.isActive ? 1 : 0); } if (updates.passwordHash !== undefined) { fields.push('password_hash = ?'); values.push(updates.passwordHash); } if (fields.length === 0) return null; fields.push('updated_at = datetime(\'now\')'); values.push(userId); const stmt = db.prepare(`UPDATE users SET ${fields.join(', ')} WHERE id = ?`); return stmt.run(...values); } /** * Update last login */ export function updateLastLogin(userId) { const stmt = db.prepare(`UPDATE users SET last_login = datetime('now'), updated_at = datetime('now') WHERE id = ?`); return stmt.run(userId); } /** * Delete user */ export function deleteUser(userId) { const stmt = db.prepare(`DELETE FROM users WHERE id = ?`); return stmt.run(userId); } // ============================================ // SESSION MANAGEMENT // ============================================ /** * Create session */ export function createSession(userId, token, expiresAt) { const stmt = db.prepare(` INSERT INTO user_sessions (user_id, session_token, expires_at, created_at) VALUES (?, ?, ?, datetime('now')) `); return stmt.run(userId, token, expiresAt); } /** * Get session by token */ export function getSessionByToken(token) { const stmt = db.prepare(` SELECT s.*, u.username, u.role, u.full_name, u.is_active FROM user_sessions s JOIN users u ON s.user_id = u.id WHERE s.session_token = ? AND s.expires_at > datetime('now') `); return stmt.get(token); } /** * Delete session */ export function deleteSession(token) { const stmt = db.prepare(`DELETE FROM user_sessions WHERE session_token = ?`); return stmt.run(token); } /** * Delete expired sessions */ export function cleanupExpiredSessions() { const stmt = db.prepare(`DELETE FROM user_sessions WHERE expires_at < datetime('now')`); return stmt.run(); } // ============================================ // AUDIT LOGGING // ============================================ /** * Log an action */ export function logAudit(userId, action, entityType, entityId = null, details = null, ipAddress = null) { const stmt = db.prepare(` INSERT INTO audit_log (user_id, action, entity_type, entity_id, details, ip_address, created_at) VALUES (?, ?, ?, ?, ?, ?, datetime('now')) `); return stmt.run(userId, action, entityType, entityId, details ? JSON.stringify(details) : null, ipAddress); } /** * Get audit log entries */ export function getAuditLog(options = {}) { const { userId, action, entityType, limit = 100, offset = 0 } = options; let where = []; let values = []; if (userId) { where.push('a.user_id = ?'); values.push(userId); } if (action) { where.push('a.action = ?'); values.push(action); } if (entityType) { where.push('a.entity_type = ?'); values.push(entityType); } const whereClause = where.length > 0 ? `WHERE ${where.join(' AND ')}` : ''; const stmt = db.prepare(` SELECT a.*, u.username FROM audit_log a LEFT JOIN users u ON a.user_id = u.id ${whereClause} ORDER BY a.created_at DESC LIMIT ? OFFSET ? `); return stmt.all(...values, limit, offset); } // ============================================ // ANALYTICS QUERIES // ============================================ /** * Get case statistics */ export function getCaseStats() { const totalCases = db.prepare(`SELECT COUNT(*) as count FROM brace_cases`).get(); const byStatus = db.prepare(` SELECT status, COUNT(*) as count FROM brace_cases GROUP BY status `).all(); const last7Days = db.prepare(` SELECT DATE(created_at) as date, COUNT(*) as count FROM brace_cases WHERE created_at >= datetime('now', '-7 days') GROUP BY DATE(created_at) ORDER BY date ASC `).all(); const last30Days = db.prepare(` SELECT DATE(created_at) as date, COUNT(*) as count FROM brace_cases WHERE created_at >= datetime('now', '-30 days') GROUP BY DATE(created_at) ORDER BY date ASC `).all(); return { total: totalCases.count, byStatus: byStatus.reduce((acc, row) => { acc[row.status] = row.count; return acc; }, {}), last7Days, last30Days }; } /** * Get Rigo classification distribution (from analysis_result JSON) */ export function getRigoDistribution() { const cases = db.prepare(` SELECT analysis_result FROM brace_cases WHERE analysis_result IS NOT NULL AND status = 'brace_generated' `).all(); const distribution = {}; for (const c of cases) { try { const result = JSON.parse(c.analysis_result); const rigoType = result.rigoType || result.rigo_classification?.type || result.brace?.rigo_classification?.type; if (rigoType) { distribution[rigoType] = (distribution[rigoType] || 0) + 1; } } catch (e) { /* skip invalid JSON */ } } return distribution; } /** * Get Cobb angle statistics */ export function getCobbAngleStats() { const cases = db.prepare(` SELECT analysis_result, landmarks_data FROM brace_cases WHERE (analysis_result IS NOT NULL OR landmarks_data IS NOT NULL) `).all(); const angles = { PT: [], MT: [], TL: [] }; for (const c of cases) { try { let cobb = null; // Try analysis_result first if (c.analysis_result) { const result = JSON.parse(c.analysis_result); cobb = result.cobbAngles || result.cobb_angles || result.brace?.cobb_angles; } // Fall back to landmarks_data if (!cobb && c.landmarks_data) { const landmarks = JSON.parse(c.landmarks_data); cobb = landmarks.cobb_angles; } if (cobb) { if (cobb.PT !== undefined) angles.PT.push(cobb.PT); if (cobb.MT !== undefined) angles.MT.push(cobb.MT); if (cobb.TL !== undefined) angles.TL.push(cobb.TL); } } catch (e) { /* skip invalid JSON */ } } const calcStats = (arr) => { if (arr.length === 0) return { min: 0, max: 0, avg: 0, count: 0 }; const sum = arr.reduce((a, b) => a + b, 0); return { min: Math.min(...arr), max: Math.max(...arr), avg: Math.round((sum / arr.length) * 10) / 10, count: arr.length }; }; return { PT: calcStats(angles.PT), MT: calcStats(angles.MT), TL: calcStats(angles.TL), totalCasesWithAngles: Math.max(angles.PT.length, angles.MT.length, angles.TL.length) }; } /** * Get processing time statistics */ export function getProcessingTimeStats() { const cases = db.prepare(` SELECT analysis_result FROM brace_cases WHERE analysis_result IS NOT NULL AND status = 'brace_generated' `).all(); const times = []; for (const c of cases) { try { const result = JSON.parse(c.analysis_result); const time = result.processing_time_ms || result.brace?.processing_time_ms; if (time) times.push(time); } catch (e) { /* skip invalid JSON */ } } if (times.length === 0) { return { min: 0, max: 0, avg: 0, count: 0 }; } const sum = times.reduce((a, b) => a + b, 0); return { min: Math.min(...times), max: Math.max(...times), avg: Math.round(sum / times.length), count: times.length }; } /** * Get body scan usage stats */ export function getBodyScanStats() { const total = db.prepare(`SELECT COUNT(*) as count FROM brace_cases WHERE status = 'brace_generated'`).get(); const withScan = db.prepare(`SELECT COUNT(*) as count FROM brace_cases WHERE status = 'brace_generated' AND body_scan_path IS NOT NULL`).get(); return { total: total.count, withBodyScan: withScan.count, withoutBodyScan: total.count - withScan.count, percentage: total.count > 0 ? Math.round((withScan.count / total.count) * 100) : 0 }; } /** * Get user statistics */ export function getUserStats() { const total = db.prepare(`SELECT COUNT(*) as count FROM users`).get(); const byRole = db.prepare(`SELECT role, COUNT(*) as count FROM users GROUP BY role`).all(); const active = db.prepare(`SELECT COUNT(*) as count FROM users WHERE is_active = 1`).get(); const recentLogins = db.prepare(` SELECT COUNT(*) as count FROM users WHERE last_login >= datetime('now', '-7 days') `).get(); return { total: total.count, active: active.count, inactive: total.count - active.count, byRole: byRole.reduce((acc, row) => { acc[row.role] = row.count; return acc; }, {}), recentLogins: recentLogins.count }; } /** * List cases with filters (for admin) */ export function listCasesFiltered(options = {}) { const { status, createdBy, search, limit = 50, offset = 0, sortBy = 'created_at', sortOrder = 'DESC' } = options; let where = []; let values = []; if (status) { where.push('c.status = ?'); values.push(status); } if (createdBy) { where.push('c.created_by = ?'); values.push(createdBy); } if (search) { where.push('c.case_id LIKE ?'); values.push(`%${search}%`); } const whereClause = where.length > 0 ? `WHERE ${where.join(' AND ')}` : ''; const validSortColumns = ['created_at', 'updated_at', 'status', 'case_id']; const sortColumn = validSortColumns.includes(sortBy) ? sortBy : 'created_at'; const order = sortOrder.toUpperCase() === 'ASC' ? 'ASC' : 'DESC'; const countStmt = db.prepare(`SELECT COUNT(*) as count FROM brace_cases c ${whereClause}`); const totalCount = countStmt.get(...values).count; const stmt = db.prepare(` SELECT c.case_id as caseId, c.case_type, c.status, c.current_step, c.notes, c.analysis_result, c.landmarks_data, c.body_scan_path, c.created_by, c.created_at, c.updated_at, u.username as created_by_username FROM brace_cases c LEFT JOIN users u ON c.created_by = u.id ${whereClause} ORDER BY c.${sortColumn} ${order} LIMIT ? OFFSET ? `); const cases = stmt.all(...values, limit, offset); return { cases, total: totalCount, limit, offset }; } export default { createCase, listCases, listCasesFiltered, getCase, updateCaseStatus, saveLandmarks, approveLandmarks, saveAnalysisResult, saveAnalysisData, saveBraceResult, saveBothBracesResult, saveMarkers, saveBodyScan, clearBodyScan, deleteCase, updateStepStatus, STEP_NAMES, // User management getUserByUsername, getUserById, listUsers, createUser, updateUser, updateLastLogin, deleteUser, // Session management createSession, getSessionByToken, deleteSession, cleanupExpiredSessions, // Audit logging logAudit, getAuditLog, // Analytics getCaseStats, getRigoDistribution, getCobbAngleStats, getProcessingTimeStats, getBodyScanStats, getUserStats };