Add patient management, deployment scripts, and Docker fixes
This commit is contained in:
699
api/db/sqlite.js
699
api/db/sqlite.js
@@ -18,10 +18,36 @@ db.pragma('journal_mode = WAL');
|
||||
|
||||
// Create tables
|
||||
db.exec(`
|
||||
-- Main cases table
|
||||
-- Patients table
|
||||
CREATE TABLE IF NOT EXISTS patients (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
mrn TEXT UNIQUE,
|
||||
first_name TEXT NOT NULL,
|
||||
last_name TEXT NOT NULL,
|
||||
date_of_birth TEXT,
|
||||
gender TEXT CHECK(gender IN ('male', 'female', 'other')),
|
||||
email TEXT,
|
||||
phone TEXT,
|
||||
address TEXT,
|
||||
diagnosis TEXT,
|
||||
curve_type TEXT,
|
||||
medical_history TEXT,
|
||||
referring_physician TEXT,
|
||||
insurance_info TEXT,
|
||||
notes TEXT,
|
||||
is_active INTEGER NOT NULL DEFAULT 1,
|
||||
created_by INTEGER,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
FOREIGN KEY (created_by) REFERENCES users(id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
-- Main cases table (linked to patients)
|
||||
CREATE TABLE IF NOT EXISTS brace_cases (
|
||||
case_id TEXT PRIMARY KEY,
|
||||
patient_id INTEGER,
|
||||
case_type TEXT NOT NULL DEFAULT 'braceflow',
|
||||
visit_date TEXT DEFAULT (date('now')),
|
||||
status TEXT NOT NULL DEFAULT 'created' CHECK(status IN (
|
||||
'created', 'running', 'completed', 'failed', 'cancelled',
|
||||
'processing_brace', 'brace_generated', 'brace_failed',
|
||||
@@ -38,9 +64,12 @@ db.exec(`
|
||||
body_scan_path TEXT DEFAULT NULL,
|
||||
body_scan_url TEXT DEFAULT NULL,
|
||||
body_scan_metadata TEXT DEFAULT NULL,
|
||||
is_archived INTEGER NOT NULL DEFAULT 0,
|
||||
archived_at TEXT DEFAULT NULL,
|
||||
created_by INTEGER DEFAULT NULL,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
updated_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
FOREIGN KEY (patient_id) REFERENCES patients(id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
-- Case steps table
|
||||
@@ -109,7 +138,35 @@ db.exec(`
|
||||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
-- API request logging table (for tracking all HTTP API calls)
|
||||
CREATE TABLE IF NOT EXISTS api_requests (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER DEFAULT NULL,
|
||||
username TEXT DEFAULT NULL,
|
||||
method TEXT NOT NULL,
|
||||
path TEXT NOT NULL,
|
||||
route_pattern TEXT DEFAULT NULL,
|
||||
query_params TEXT DEFAULT NULL,
|
||||
request_params TEXT DEFAULT NULL,
|
||||
file_uploads TEXT DEFAULT NULL,
|
||||
status_code INTEGER DEFAULT NULL,
|
||||
response_time_ms INTEGER DEFAULT NULL,
|
||||
response_summary TEXT DEFAULT NULL,
|
||||
ip_address TEXT DEFAULT NULL,
|
||||
user_agent TEXT DEFAULT NULL,
|
||||
request_body_size INTEGER DEFAULT NULL,
|
||||
response_body_size INTEGER DEFAULT NULL,
|
||||
error_message 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_patients_name ON patients(last_name, first_name);
|
||||
CREATE INDEX IF NOT EXISTS idx_patients_mrn ON patients(mrn);
|
||||
CREATE INDEX IF NOT EXISTS idx_patients_created_by ON patients(created_by);
|
||||
CREATE INDEX IF NOT EXISTS idx_patients_active ON patients(is_active);
|
||||
CREATE INDEX IF NOT EXISTS idx_cases_patient ON brace_cases(patient_id);
|
||||
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);
|
||||
@@ -120,6 +177,11 @@ db.exec(`
|
||||
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);
|
||||
CREATE INDEX IF NOT EXISTS idx_api_requests_user ON api_requests(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_api_requests_path ON api_requests(path);
|
||||
CREATE INDEX IF NOT EXISTS idx_api_requests_method ON api_requests(method);
|
||||
CREATE INDEX IF NOT EXISTS idx_api_requests_status ON api_requests(status_code);
|
||||
CREATE INDEX IF NOT EXISTS idx_api_requests_created ON api_requests(created_at);
|
||||
`);
|
||||
|
||||
// Migration: Add new columns to existing tables
|
||||
@@ -143,6 +205,42 @@ try {
|
||||
db.exec(`ALTER TABLE brace_cases ADD COLUMN created_by INTEGER DEFAULT NULL`);
|
||||
} catch (e) { /* Column already exists */ }
|
||||
|
||||
// Migration: Add new columns to api_requests table for enhanced logging
|
||||
try {
|
||||
db.exec(`ALTER TABLE api_requests ADD COLUMN route_pattern TEXT DEFAULT NULL`);
|
||||
} catch (e) { /* Column already exists */ }
|
||||
|
||||
try {
|
||||
db.exec(`ALTER TABLE api_requests ADD COLUMN request_params TEXT DEFAULT NULL`);
|
||||
} catch (e) { /* Column already exists */ }
|
||||
|
||||
try {
|
||||
db.exec(`ALTER TABLE api_requests ADD COLUMN file_uploads TEXT DEFAULT NULL`);
|
||||
} catch (e) { /* Column already exists */ }
|
||||
|
||||
try {
|
||||
db.exec(`ALTER TABLE api_requests ADD COLUMN response_summary TEXT DEFAULT NULL`);
|
||||
} catch (e) { /* Column already exists */ }
|
||||
|
||||
// Migration: Add patient_id to brace_cases
|
||||
try {
|
||||
db.exec(`ALTER TABLE brace_cases ADD COLUMN patient_id INTEGER DEFAULT NULL`);
|
||||
} catch (e) { /* Column already exists */ }
|
||||
|
||||
// Migration: Add visit_date to brace_cases
|
||||
try {
|
||||
db.exec(`ALTER TABLE brace_cases ADD COLUMN visit_date TEXT DEFAULT NULL`);
|
||||
} catch (e) { /* Column already exists */ }
|
||||
|
||||
// Migration: Add is_archived to brace_cases
|
||||
try {
|
||||
db.exec(`ALTER TABLE brace_cases ADD COLUMN is_archived INTEGER NOT NULL DEFAULT 0`);
|
||||
} catch (e) { /* Column already exists */ }
|
||||
|
||||
try {
|
||||
db.exec(`ALTER TABLE brace_cases ADD COLUMN archived_at TEXT 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 {
|
||||
@@ -168,12 +266,12 @@ const STEP_NAMES = [
|
||||
];
|
||||
|
||||
/**
|
||||
* Create a new case
|
||||
* Create a new case (optionally linked to a patient)
|
||||
*/
|
||||
export function createCase(caseId, caseType = 'braceflow', notes = null) {
|
||||
export function createCase(caseId, caseType = 'braceflow', notes = null, patientId = null, visitDate = 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'))
|
||||
INSERT INTO brace_cases (case_id, patient_id, case_type, visit_date, status, notes, created_at, updated_at)
|
||||
VALUES (?, ?, ?, ?, 'created', ?, datetime('now'), datetime('now'))
|
||||
`);
|
||||
|
||||
const insertStep = db.prepare(`
|
||||
@@ -182,40 +280,108 @@ export function createCase(caseId, caseType = 'braceflow', notes = null) {
|
||||
`);
|
||||
|
||||
const transaction = db.transaction(() => {
|
||||
insertCase.run(caseId, caseType, notes);
|
||||
insertCase.run(caseId, patientId, caseType, visitDate || new Date().toISOString().split('T')[0], notes);
|
||||
STEP_NAMES.forEach((stepName, idx) => {
|
||||
insertStep.run(caseId, stepName, idx + 1);
|
||||
});
|
||||
});
|
||||
|
||||
transaction();
|
||||
return { caseId, status: 'created', steps: STEP_NAMES };
|
||||
return { caseId, patientId, status: 'created', steps: STEP_NAMES };
|
||||
}
|
||||
|
||||
/**
|
||||
* List all cases
|
||||
* List all cases with patient info
|
||||
* @param {Object} options - Query options
|
||||
* @param {boolean} options.includeArchived - Include archived cases (for admin view)
|
||||
* @param {boolean} options.archivedOnly - Only show archived cases
|
||||
*/
|
||||
export function listCases() {
|
||||
export function listCases(options = {}) {
|
||||
const { includeArchived = false, archivedOnly = false } = options;
|
||||
|
||||
let whereClause = '';
|
||||
if (archivedOnly) {
|
||||
whereClause = 'WHERE c.is_archived = 1';
|
||||
} else if (!includeArchived) {
|
||||
whereClause = 'WHERE c.is_archived = 0';
|
||||
}
|
||||
|
||||
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
|
||||
SELECT c.case_id as caseId, c.patient_id, c.case_type, c.visit_date, c.status, c.current_step, c.notes,
|
||||
c.analysis_result, c.landmarks_data, c.is_archived, c.archived_at, c.created_at, c.updated_at,
|
||||
p.first_name as patient_first_name, p.last_name as patient_last_name,
|
||||
p.mrn as patient_mrn
|
||||
FROM brace_cases c
|
||||
LEFT JOIN patients p ON c.patient_id = p.id
|
||||
${whereClause}
|
||||
ORDER BY c.created_at DESC
|
||||
`);
|
||||
return stmt.all();
|
||||
|
||||
const rows = stmt.all();
|
||||
|
||||
// Transform to include patient object
|
||||
return rows.map(row => ({
|
||||
caseId: row.caseId,
|
||||
patient_id: row.patient_id,
|
||||
patient: row.patient_id ? {
|
||||
id: row.patient_id,
|
||||
firstName: row.patient_first_name,
|
||||
lastName: row.patient_last_name,
|
||||
fullName: `${row.patient_first_name} ${row.patient_last_name}`,
|
||||
mrn: row.patient_mrn
|
||||
} : null,
|
||||
case_type: row.case_type,
|
||||
visit_date: row.visit_date,
|
||||
status: row.status,
|
||||
current_step: row.current_step,
|
||||
notes: row.notes,
|
||||
analysis_result: row.analysis_result,
|
||||
landmarks_data: row.landmarks_data,
|
||||
is_archived: row.is_archived === 1,
|
||||
archived_at: row.archived_at,
|
||||
created_at: row.created_at,
|
||||
updated_at: row.updated_at
|
||||
}));
|
||||
}
|
||||
|
||||
/**
|
||||
* Get case by ID with steps
|
||||
* Archive a case (soft delete)
|
||||
*/
|
||||
export function archiveCase(caseId) {
|
||||
const stmt = db.prepare(`
|
||||
UPDATE brace_cases
|
||||
SET is_archived = 1, archived_at = datetime('now'), updated_at = datetime('now')
|
||||
WHERE case_id = ?
|
||||
`);
|
||||
return stmt.run(caseId);
|
||||
}
|
||||
|
||||
/**
|
||||
* Unarchive a case
|
||||
*/
|
||||
export function unarchiveCase(caseId) {
|
||||
const stmt = db.prepare(`
|
||||
UPDATE brace_cases
|
||||
SET is_archived = 0, archived_at = NULL, updated_at = datetime('now')
|
||||
WHERE case_id = ?
|
||||
`);
|
||||
return stmt.run(caseId);
|
||||
}
|
||||
|
||||
/**
|
||||
* Get case by ID with steps and patient info
|
||||
*/
|
||||
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 = ?
|
||||
SELECT c.case_id, c.patient_id, c.case_type, c.visit_date, c.status, c.current_step, c.notes,
|
||||
c.analysis_result, c.landmarks_data, c.analysis_data, c.markers_data,
|
||||
c.body_scan_path, c.body_scan_url, c.body_scan_metadata,
|
||||
c.created_at, c.updated_at,
|
||||
p.first_name as patient_first_name, p.last_name as patient_last_name,
|
||||
p.mrn as patient_mrn, p.date_of_birth as patient_dob, p.gender as patient_gender
|
||||
FROM brace_cases c
|
||||
LEFT JOIN patients p ON c.patient_id = p.id
|
||||
WHERE c.case_id = ?
|
||||
`);
|
||||
|
||||
const stepsStmt = db.prepare(`
|
||||
@@ -267,9 +433,23 @@ export function getCase(caseId) {
|
||||
}
|
||||
} catch (e) { /* ignore */ }
|
||||
|
||||
// Build patient object if patient_id exists
|
||||
const patient = caseData.patient_id ? {
|
||||
id: caseData.patient_id,
|
||||
firstName: caseData.patient_first_name,
|
||||
lastName: caseData.patient_last_name,
|
||||
fullName: `${caseData.patient_first_name} ${caseData.patient_last_name}`,
|
||||
mrn: caseData.patient_mrn,
|
||||
dateOfBirth: caseData.patient_dob,
|
||||
gender: caseData.patient_gender
|
||||
} : null;
|
||||
|
||||
return {
|
||||
caseId: caseData.case_id,
|
||||
patient_id: caseData.patient_id,
|
||||
patient,
|
||||
case_type: caseData.case_type,
|
||||
visit_date: caseData.visit_date,
|
||||
status: caseData.status,
|
||||
current_step: caseData.current_step,
|
||||
notes: caseData.notes,
|
||||
@@ -458,6 +638,244 @@ export function updateStepStatus(caseId, stepName, status, errorMessage = null)
|
||||
return stmt.run(status, errorMessage, status, status, caseId, stepName);
|
||||
}
|
||||
|
||||
// ============================================
|
||||
// PATIENT MANAGEMENT
|
||||
// ============================================
|
||||
|
||||
/**
|
||||
* Create a new patient
|
||||
*/
|
||||
export function createPatient(data) {
|
||||
const stmt = db.prepare(`
|
||||
INSERT INTO patients (
|
||||
mrn, first_name, last_name, date_of_birth, gender,
|
||||
email, phone, address, diagnosis, curve_type,
|
||||
medical_history, referring_physician, insurance_info, notes,
|
||||
created_by, created_at, updated_at
|
||||
)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, datetime('now'), datetime('now'))
|
||||
`);
|
||||
|
||||
const result = stmt.run(
|
||||
data.mrn || null,
|
||||
data.firstName,
|
||||
data.lastName,
|
||||
data.dateOfBirth || null,
|
||||
data.gender || null,
|
||||
data.email || null,
|
||||
data.phone || null,
|
||||
data.address || null,
|
||||
data.diagnosis || null,
|
||||
data.curveType || null,
|
||||
data.medicalHistory || null,
|
||||
data.referringPhysician || null,
|
||||
data.insuranceInfo || null,
|
||||
data.notes || null,
|
||||
data.createdBy || null
|
||||
);
|
||||
|
||||
return {
|
||||
id: result.lastInsertRowid,
|
||||
...data
|
||||
};
|
||||
}
|
||||
|
||||
/**
|
||||
* Get patient by ID
|
||||
*/
|
||||
export function getPatient(patientId) {
|
||||
const stmt = db.prepare(`
|
||||
SELECT p.*, u.username as created_by_username
|
||||
FROM patients p
|
||||
LEFT JOIN users u ON p.created_by = u.id
|
||||
WHERE p.id = ?
|
||||
`);
|
||||
return stmt.get(patientId);
|
||||
}
|
||||
|
||||
/**
|
||||
* List all patients with optional filters
|
||||
*/
|
||||
export function listPatients(options = {}) {
|
||||
const { search, isActive = true, createdBy, limit = 50, offset = 0, sortBy = 'created_at', sortOrder = 'DESC' } = options;
|
||||
|
||||
let where = [];
|
||||
let values = [];
|
||||
|
||||
if (isActive !== undefined && isActive !== null) {
|
||||
where.push('p.is_active = ?');
|
||||
values.push(isActive ? 1 : 0);
|
||||
}
|
||||
|
||||
if (createdBy) {
|
||||
where.push('p.created_by = ?');
|
||||
values.push(createdBy);
|
||||
}
|
||||
|
||||
if (search) {
|
||||
where.push('(p.first_name LIKE ? OR p.last_name LIKE ? OR p.mrn LIKE ? OR p.email LIKE ?)');
|
||||
const searchPattern = `%${search}%`;
|
||||
values.push(searchPattern, searchPattern, searchPattern, searchPattern);
|
||||
}
|
||||
|
||||
const whereClause = where.length > 0 ? `WHERE ${where.join(' AND ')}` : '';
|
||||
const validSortColumns = ['created_at', 'updated_at', 'last_name', 'first_name', 'date_of_birth'];
|
||||
const sortColumn = validSortColumns.includes(sortBy) ? sortBy : 'created_at';
|
||||
const order = sortOrder.toUpperCase() === 'ASC' ? 'ASC' : 'DESC';
|
||||
|
||||
// Get total count
|
||||
const countStmt = db.prepare(`SELECT COUNT(*) as count FROM patients p ${whereClause}`);
|
||||
const totalCount = countStmt.get(...values).count;
|
||||
|
||||
// Get patients with case count
|
||||
const stmt = db.prepare(`
|
||||
SELECT p.*,
|
||||
u.username as created_by_username,
|
||||
(SELECT COUNT(*) FROM brace_cases c WHERE c.patient_id = p.id) as case_count,
|
||||
(SELECT MAX(c.created_at) FROM brace_cases c WHERE c.patient_id = p.id) as last_visit
|
||||
FROM patients p
|
||||
LEFT JOIN users u ON p.created_by = u.id
|
||||
${whereClause}
|
||||
ORDER BY p.${sortColumn} ${order}
|
||||
LIMIT ? OFFSET ?
|
||||
`);
|
||||
|
||||
const patients = stmt.all(...values, limit, offset);
|
||||
|
||||
return {
|
||||
patients,
|
||||
total: totalCount,
|
||||
limit,
|
||||
offset
|
||||
};
|
||||
}
|
||||
|
||||
/**
|
||||
* Update patient
|
||||
*/
|
||||
export function updatePatient(patientId, data) {
|
||||
const fields = [];
|
||||
const values = [];
|
||||
|
||||
if (data.mrn !== undefined) { fields.push('mrn = ?'); values.push(data.mrn); }
|
||||
if (data.firstName !== undefined) { fields.push('first_name = ?'); values.push(data.firstName); }
|
||||
if (data.lastName !== undefined) { fields.push('last_name = ?'); values.push(data.lastName); }
|
||||
if (data.dateOfBirth !== undefined) { fields.push('date_of_birth = ?'); values.push(data.dateOfBirth); }
|
||||
if (data.gender !== undefined) { fields.push('gender = ?'); values.push(data.gender); }
|
||||
if (data.email !== undefined) { fields.push('email = ?'); values.push(data.email); }
|
||||
if (data.phone !== undefined) { fields.push('phone = ?'); values.push(data.phone); }
|
||||
if (data.address !== undefined) { fields.push('address = ?'); values.push(data.address); }
|
||||
if (data.diagnosis !== undefined) { fields.push('diagnosis = ?'); values.push(data.diagnosis); }
|
||||
if (data.curveType !== undefined) { fields.push('curve_type = ?'); values.push(data.curveType); }
|
||||
if (data.medicalHistory !== undefined) { fields.push('medical_history = ?'); values.push(data.medicalHistory); }
|
||||
if (data.referringPhysician !== undefined) { fields.push('referring_physician = ?'); values.push(data.referringPhysician); }
|
||||
if (data.insuranceInfo !== undefined) { fields.push('insurance_info = ?'); values.push(data.insuranceInfo); }
|
||||
if (data.notes !== undefined) { fields.push('notes = ?'); values.push(data.notes); }
|
||||
if (data.isActive !== undefined) { fields.push('is_active = ?'); values.push(data.isActive ? 1 : 0); }
|
||||
|
||||
if (fields.length === 0) return null;
|
||||
|
||||
fields.push('updated_at = datetime(\'now\')');
|
||||
values.push(patientId);
|
||||
|
||||
const stmt = db.prepare(`UPDATE patients SET ${fields.join(', ')} WHERE id = ?`);
|
||||
return stmt.run(...values);
|
||||
}
|
||||
|
||||
/**
|
||||
* Archive patient (soft delete - set is_active = 0)
|
||||
*/
|
||||
export function archivePatient(patientId) {
|
||||
const stmt = db.prepare(`
|
||||
UPDATE patients
|
||||
SET is_active = 0, updated_at = datetime('now')
|
||||
WHERE id = ?
|
||||
`);
|
||||
return stmt.run(patientId);
|
||||
}
|
||||
|
||||
/**
|
||||
* Unarchive patient (restore - set is_active = 1)
|
||||
*/
|
||||
export function unarchivePatient(patientId) {
|
||||
const stmt = db.prepare(`
|
||||
UPDATE patients
|
||||
SET is_active = 1, updated_at = datetime('now')
|
||||
WHERE id = ?
|
||||
`);
|
||||
return stmt.run(patientId);
|
||||
}
|
||||
|
||||
/**
|
||||
* Delete patient - kept for backwards compatibility, now archives
|
||||
*/
|
||||
export function deletePatient(patientId, hard = false) {
|
||||
if (hard) {
|
||||
// Hard delete should never be used in normal operation
|
||||
const stmt = db.prepare(`DELETE FROM patients WHERE id = ?`);
|
||||
return stmt.run(patientId);
|
||||
} else {
|
||||
return archivePatient(patientId);
|
||||
}
|
||||
}
|
||||
|
||||
/**
|
||||
* Get cases for a patient
|
||||
* @param {number} patientId - Patient ID
|
||||
* @param {Object} options - Query options
|
||||
* @param {boolean} options.includeArchived - Include archived cases
|
||||
*/
|
||||
export function getPatientCases(patientId, options = {}) {
|
||||
const { includeArchived = false } = options;
|
||||
|
||||
const archivedFilter = includeArchived ? '' : 'AND is_archived = 0';
|
||||
|
||||
const stmt = db.prepare(`
|
||||
SELECT case_id, case_type, status, current_step, visit_date, notes,
|
||||
analysis_result, landmarks_data, body_scan_path, body_scan_url,
|
||||
is_archived, archived_at, created_at, updated_at
|
||||
FROM brace_cases
|
||||
WHERE patient_id = ? ${archivedFilter}
|
||||
ORDER BY created_at DESC
|
||||
`);
|
||||
return stmt.all(patientId);
|
||||
}
|
||||
|
||||
/**
|
||||
* Get patient statistics
|
||||
*/
|
||||
export function getPatientStats() {
|
||||
const total = db.prepare(`SELECT COUNT(*) as count FROM patients`).get();
|
||||
const active = db.prepare(`SELECT COUNT(*) as count FROM patients WHERE is_active = 1`).get();
|
||||
const withCases = db.prepare(`
|
||||
SELECT COUNT(DISTINCT patient_id) as count
|
||||
FROM brace_cases
|
||||
WHERE patient_id IS NOT NULL
|
||||
`).get();
|
||||
|
||||
const byGender = db.prepare(`
|
||||
SELECT gender, COUNT(*) as count
|
||||
FROM patients
|
||||
WHERE is_active = 1
|
||||
GROUP BY gender
|
||||
`).all();
|
||||
|
||||
const recentPatients = db.prepare(`
|
||||
SELECT COUNT(*) as count
|
||||
FROM patients
|
||||
WHERE created_at >= datetime('now', '-30 days')
|
||||
`).get();
|
||||
|
||||
return {
|
||||
total: total.count,
|
||||
active: active.count,
|
||||
inactive: total.count - active.count,
|
||||
withCases: withCases.count,
|
||||
byGender: byGender.reduce((acc, row) => { acc[row.gender || 'unspecified'] = row.count; return acc; }, {}),
|
||||
recentPatients: recentPatients.count
|
||||
};
|
||||
}
|
||||
|
||||
// ============================================
|
||||
// USER MANAGEMENT
|
||||
// ============================================
|
||||
@@ -631,6 +1049,210 @@ export function getAuditLog(options = {}) {
|
||||
return stmt.all(...values, limit, offset);
|
||||
}
|
||||
|
||||
// ============================================
|
||||
// API REQUEST LOGGING
|
||||
// ============================================
|
||||
|
||||
/**
|
||||
* Log an API request with full details
|
||||
*/
|
||||
export function logApiRequest(data) {
|
||||
const stmt = db.prepare(`
|
||||
INSERT INTO api_requests (
|
||||
user_id, username, method, path, route_pattern, query_params,
|
||||
request_params, file_uploads, status_code, response_time_ms,
|
||||
response_summary, ip_address, user_agent, request_body_size,
|
||||
response_body_size, error_message, created_at
|
||||
)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, datetime('now'))
|
||||
`);
|
||||
|
||||
return stmt.run(
|
||||
data.userId || null,
|
||||
data.username || null,
|
||||
data.method,
|
||||
data.path,
|
||||
data.routePattern || null,
|
||||
data.queryParams ? JSON.stringify(data.queryParams) : null,
|
||||
data.requestParams ? JSON.stringify(data.requestParams) : null,
|
||||
data.fileUploads ? JSON.stringify(data.fileUploads) : null,
|
||||
data.statusCode || null,
|
||||
data.responseTimeMs || null,
|
||||
data.responseSummary ? JSON.stringify(data.responseSummary) : null,
|
||||
data.ipAddress || null,
|
||||
data.userAgent || null,
|
||||
data.requestBodySize || null,
|
||||
data.responseBodySize || null,
|
||||
data.errorMessage || null
|
||||
);
|
||||
}
|
||||
|
||||
/**
|
||||
* Get API request logs with filters
|
||||
*/
|
||||
export function getApiRequests(options = {}) {
|
||||
const {
|
||||
userId,
|
||||
username,
|
||||
method,
|
||||
path,
|
||||
statusCode,
|
||||
minStatusCode,
|
||||
maxStatusCode,
|
||||
startDate,
|
||||
endDate,
|
||||
limit = 100,
|
||||
offset = 0
|
||||
} = options;
|
||||
|
||||
let where = [];
|
||||
let values = [];
|
||||
|
||||
if (userId) { where.push('user_id = ?'); values.push(userId); }
|
||||
if (username) { where.push('username LIKE ?'); values.push(`%${username}%`); }
|
||||
if (method) { where.push('method = ?'); values.push(method); }
|
||||
if (path) { where.push('path LIKE ?'); values.push(`%${path}%`); }
|
||||
if (statusCode) { where.push('status_code = ?'); values.push(statusCode); }
|
||||
if (minStatusCode) { where.push('status_code >= ?'); values.push(minStatusCode); }
|
||||
if (maxStatusCode) { where.push('status_code < ?'); values.push(maxStatusCode); }
|
||||
if (startDate) { where.push('created_at >= ?'); values.push(startDate); }
|
||||
if (endDate) { where.push('created_at <= ?'); values.push(endDate); }
|
||||
|
||||
const whereClause = where.length > 0 ? `WHERE ${where.join(' AND ')}` : '';
|
||||
|
||||
// Get total count
|
||||
const countStmt = db.prepare(`SELECT COUNT(*) as count FROM api_requests ${whereClause}`);
|
||||
const totalCount = countStmt.get(...values).count;
|
||||
|
||||
// Get paginated results
|
||||
const stmt = db.prepare(`
|
||||
SELECT *
|
||||
FROM api_requests
|
||||
${whereClause}
|
||||
ORDER BY created_at DESC
|
||||
LIMIT ? OFFSET ?
|
||||
`);
|
||||
|
||||
const requests = stmt.all(...values, limit, offset);
|
||||
|
||||
return {
|
||||
requests,
|
||||
total: totalCount,
|
||||
limit,
|
||||
offset
|
||||
};
|
||||
}
|
||||
|
||||
/**
|
||||
* Get API request statistics
|
||||
*/
|
||||
export function getApiRequestStats(options = {}) {
|
||||
const { startDate, endDate } = options;
|
||||
|
||||
let where = [];
|
||||
let values = [];
|
||||
|
||||
if (startDate) { where.push('created_at >= ?'); values.push(startDate); }
|
||||
if (endDate) { where.push('created_at <= ?'); values.push(endDate); }
|
||||
|
||||
const whereClause = where.length > 0 ? `WHERE ${where.join(' AND ')}` : '';
|
||||
|
||||
// Total requests
|
||||
const total = db.prepare(`SELECT COUNT(*) as count FROM api_requests ${whereClause}`).get(...values);
|
||||
|
||||
// By method
|
||||
const byMethod = db.prepare(`
|
||||
SELECT method, COUNT(*) as count
|
||||
FROM api_requests ${whereClause}
|
||||
GROUP BY method ORDER BY count DESC
|
||||
`).all(...values);
|
||||
|
||||
// By status code category
|
||||
const byStatusCategory = db.prepare(`
|
||||
SELECT
|
||||
CASE
|
||||
WHEN status_code >= 200 AND status_code < 300 THEN '2xx Success'
|
||||
WHEN status_code >= 300 AND status_code < 400 THEN '3xx Redirect'
|
||||
WHEN status_code >= 400 AND status_code < 500 THEN '4xx Client Error'
|
||||
WHEN status_code >= 500 THEN '5xx Server Error'
|
||||
ELSE 'Unknown'
|
||||
END as category,
|
||||
COUNT(*) as count
|
||||
FROM api_requests ${whereClause}
|
||||
GROUP BY category ORDER BY count DESC
|
||||
`).all(...values);
|
||||
|
||||
// Top endpoints
|
||||
const topEndpoints = db.prepare(`
|
||||
SELECT method, path, COUNT(*) as count,
|
||||
AVG(response_time_ms) as avg_response_time
|
||||
FROM api_requests ${whereClause}
|
||||
GROUP BY method, path
|
||||
ORDER BY count DESC
|
||||
LIMIT 20
|
||||
`).all(...values);
|
||||
|
||||
// Top users
|
||||
const topUsers = db.prepare(`
|
||||
SELECT user_id, username, COUNT(*) as count
|
||||
FROM api_requests
|
||||
${whereClause ? whereClause + ' AND username IS NOT NULL' : 'WHERE username IS NOT NULL'}
|
||||
GROUP BY user_id, username
|
||||
ORDER BY count DESC
|
||||
LIMIT 10
|
||||
`).all(...values);
|
||||
|
||||
// Average response time
|
||||
const avgResponseTime = db.prepare(`
|
||||
SELECT AVG(response_time_ms) as avg,
|
||||
MIN(response_time_ms) as min,
|
||||
MAX(response_time_ms) as max
|
||||
FROM api_requests
|
||||
${whereClause ? whereClause + ' AND response_time_ms IS NOT NULL' : 'WHERE response_time_ms IS NOT NULL'}
|
||||
`).get(...values);
|
||||
|
||||
// Requests per hour (last 24 hours)
|
||||
const requestsPerHour = db.prepare(`
|
||||
SELECT strftime('%Y-%m-%d %H:00', created_at) as hour, COUNT(*) as count
|
||||
FROM api_requests
|
||||
WHERE created_at >= datetime('now', '-24 hours')
|
||||
GROUP BY hour
|
||||
ORDER BY hour ASC
|
||||
`).all();
|
||||
|
||||
// Error rate
|
||||
const errors = db.prepare(`
|
||||
SELECT COUNT(*) as count FROM api_requests
|
||||
${whereClause ? whereClause + ' AND status_code >= 400' : 'WHERE status_code >= 400'}
|
||||
`).get(...values);
|
||||
|
||||
return {
|
||||
total: total.count,
|
||||
byMethod: byMethod.reduce((acc, row) => { acc[row.method] = row.count; return acc; }, {}),
|
||||
byStatusCategory: byStatusCategory.reduce((acc, row) => { acc[row.category] = row.count; return acc; }, {}),
|
||||
topEndpoints,
|
||||
topUsers,
|
||||
responseTime: {
|
||||
avg: Math.round(avgResponseTime?.avg || 0),
|
||||
min: avgResponseTime?.min || 0,
|
||||
max: avgResponseTime?.max || 0
|
||||
},
|
||||
requestsPerHour,
|
||||
errorRate: total.count > 0 ? Math.round((errors.count / total.count) * 100 * 10) / 10 : 0
|
||||
};
|
||||
}
|
||||
|
||||
/**
|
||||
* Cleanup old API request logs (older than N days)
|
||||
*/
|
||||
export function cleanupOldApiRequests(daysToKeep = 30) {
|
||||
const stmt = db.prepare(`
|
||||
DELETE FROM api_requests
|
||||
WHERE created_at < datetime('now', '-' || ? || ' days')
|
||||
`);
|
||||
return stmt.run(daysToKeep);
|
||||
}
|
||||
|
||||
// ============================================
|
||||
// ANALYTICS QUERIES
|
||||
// ============================================
|
||||
@@ -819,7 +1441,7 @@ export function getUserStats() {
|
||||
* List cases with filters (for admin)
|
||||
*/
|
||||
export function listCasesFiltered(options = {}) {
|
||||
const { status, createdBy, search, limit = 50, offset = 0, sortBy = 'created_at', sortOrder = 'DESC' } = options;
|
||||
const { status, createdBy, search, limit = 50, offset = 0, sortBy = 'created_at', sortOrder = 'DESC', includeArchived = false, archivedOnly = false } = options;
|
||||
|
||||
let where = [];
|
||||
let values = [];
|
||||
@@ -828,6 +1450,13 @@ export function listCasesFiltered(options = {}) {
|
||||
if (createdBy) { where.push('c.created_by = ?'); values.push(createdBy); }
|
||||
if (search) { where.push('c.case_id LIKE ?'); values.push(`%${search}%`); }
|
||||
|
||||
// Archive filtering
|
||||
if (archivedOnly) {
|
||||
where.push('c.is_archived = 1');
|
||||
} else if (!includeArchived) {
|
||||
where.push('c.is_archived = 0');
|
||||
}
|
||||
|
||||
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';
|
||||
@@ -839,6 +1468,7 @@ export function listCasesFiltered(options = {}) {
|
||||
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.is_archived, c.archived_at,
|
||||
c.created_by, c.created_at, c.updated_at,
|
||||
u.username as created_by_username
|
||||
FROM brace_cases c
|
||||
@@ -848,7 +1478,10 @@ export function listCasesFiltered(options = {}) {
|
||||
LIMIT ? OFFSET ?
|
||||
`);
|
||||
|
||||
const cases = stmt.all(...values, limit, offset);
|
||||
const cases = stmt.all(...values, limit, offset).map(row => ({
|
||||
...row,
|
||||
is_archived: row.is_archived === 1
|
||||
}));
|
||||
|
||||
return {
|
||||
cases,
|
||||
@@ -859,6 +1492,7 @@ export function listCasesFiltered(options = {}) {
|
||||
}
|
||||
|
||||
export default {
|
||||
// Case management
|
||||
createCase,
|
||||
listCases,
|
||||
listCasesFiltered,
|
||||
@@ -874,8 +1508,20 @@ export default {
|
||||
saveBodyScan,
|
||||
clearBodyScan,
|
||||
deleteCase,
|
||||
archiveCase,
|
||||
unarchiveCase,
|
||||
updateStepStatus,
|
||||
STEP_NAMES,
|
||||
// Patient management
|
||||
createPatient,
|
||||
getPatient,
|
||||
listPatients,
|
||||
updatePatient,
|
||||
deletePatient,
|
||||
archivePatient,
|
||||
unarchivePatient,
|
||||
getPatientCases,
|
||||
getPatientStats,
|
||||
// User management
|
||||
getUserByUsername,
|
||||
getUserById,
|
||||
@@ -892,6 +1538,11 @@ export default {
|
||||
// Audit logging
|
||||
logAudit,
|
||||
getAuditLog,
|
||||
// API request logging
|
||||
logApiRequest,
|
||||
getApiRequests,
|
||||
getApiRequestStats,
|
||||
cleanupOldApiRequests,
|
||||
// Analytics
|
||||
getCaseStats,
|
||||
getRigoDistribution,
|
||||
|
||||
Reference in New Issue
Block a user