feat: añadir migrador de migraciones up-only para SQLite
Co-authored-by: aider (openrouter/openai/gpt-5) <aider@aider.chat>pull/1/head
parent
4a305dc007
commit
efe8aaef89
@ -0,0 +1,119 @@
|
||||
import type { Database } from 'bun:sqlite';
|
||||
|
||||
export type Migration = {
|
||||
version: number;
|
||||
name: string;
|
||||
checksum: string; // estático para trazabilidad básica
|
||||
up: (db: Database) => void | Promise<void>;
|
||||
};
|
||||
|
||||
function tableHasColumn(db: Database, table: string, column: string): boolean {
|
||||
const cols = db.query(`PRAGMA table_info(${table})`).all() as any[];
|
||||
return Array.isArray(cols) && cols.some((c: any) => c.name === column);
|
||||
}
|
||||
|
||||
export const migrations: Migration[] = [
|
||||
{
|
||||
version: 1,
|
||||
name: 'initial-schema',
|
||||
checksum: 'v1-initial-schema-2025-09-06',
|
||||
up: (db: Database) => {
|
||||
// Esquema inicial (equivalente al initializeDatabase actual)
|
||||
db.exec(`PRAGMA foreign_keys = ON;`);
|
||||
|
||||
db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
id TEXT PRIMARY KEY,
|
||||
first_seen TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%f', 'now')),
|
||||
last_seen TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%f', 'now'))
|
||||
);
|
||||
`);
|
||||
|
||||
db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS groups (
|
||||
id TEXT PRIMARY KEY,
|
||||
community_id TEXT NOT NULL,
|
||||
name TEXT,
|
||||
last_verified TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%f', 'now')),
|
||||
active BOOLEAN DEFAULT TRUE
|
||||
);
|
||||
`);
|
||||
|
||||
db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS tasks (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
description TEXT NOT NULL,
|
||||
created_at TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%f', 'now')),
|
||||
due_date TEXT NULL,
|
||||
completed BOOLEAN DEFAULT FALSE,
|
||||
completed_at TEXT NULL,
|
||||
group_id TEXT NULL,
|
||||
created_by TEXT NOT NULL,
|
||||
completed_by TEXT NULL,
|
||||
FOREIGN KEY (created_by) REFERENCES users(id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (completed_by) REFERENCES users(id) ON DELETE SET NULL,
|
||||
FOREIGN KEY (group_id) REFERENCES groups(id) ON DELETE SET NULL
|
||||
);
|
||||
`);
|
||||
|
||||
db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS task_assignments (
|
||||
task_id INTEGER NOT NULL,
|
||||
user_id TEXT NOT NULL,
|
||||
assigned_by TEXT NOT NULL,
|
||||
assigned_at TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%f', 'now')),
|
||||
PRIMARY KEY (task_id, user_id),
|
||||
FOREIGN KEY (task_id) REFERENCES tasks(id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (assigned_by) REFERENCES users(id) ON DELETE CASCADE
|
||||
);
|
||||
`);
|
||||
|
||||
db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS response_queue (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
recipient TEXT NOT NULL,
|
||||
message TEXT NOT NULL,
|
||||
status TEXT NOT NULL DEFAULT 'queued' CHECK (status IN ('queued','processing','sent','failed')),
|
||||
attempts INTEGER NOT NULL DEFAULT 0,
|
||||
last_error TEXT NULL,
|
||||
metadata TEXT NULL,
|
||||
created_at TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%f', 'now')),
|
||||
updated_at TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%f', 'now'))
|
||||
);
|
||||
`);
|
||||
|
||||
db.exec(`
|
||||
CREATE INDEX IF NOT EXISTS idx_response_queue_status_created_at
|
||||
ON response_queue (status, created_at);
|
||||
`);
|
||||
}
|
||||
},
|
||||
{
|
||||
version: 2,
|
||||
name: 'response-queue-reliability',
|
||||
checksum: 'v2-rq-reliability-2025-09-06',
|
||||
up: (db: Database) => {
|
||||
// Añadir columnas necesarias si no existen (idempotente)
|
||||
if (!tableHasColumn(db, 'response_queue', 'next_attempt_at')) {
|
||||
db.exec(`ALTER TABLE response_queue ADD COLUMN next_attempt_at TEXT NULL;`);
|
||||
}
|
||||
if (!tableHasColumn(db, 'response_queue', 'lease_until')) {
|
||||
db.exec(`ALTER TABLE response_queue ADD COLUMN lease_until TEXT NULL;`);
|
||||
}
|
||||
if (!tableHasColumn(db, 'response_queue', 'last_status_code')) {
|
||||
db.exec(`ALTER TABLE response_queue ADD COLUMN last_status_code INTEGER NULL;`);
|
||||
}
|
||||
|
||||
// Índices complementarios
|
||||
db.exec(`
|
||||
CREATE INDEX IF NOT EXISTS idx_response_queue_status_next_attempt
|
||||
ON response_queue (status, next_attempt_at);
|
||||
`);
|
||||
db.exec(`
|
||||
CREATE INDEX IF NOT EXISTS idx_response_queue_status_lease_until
|
||||
ON response_queue (status, lease_until);
|
||||
`);
|
||||
}
|
||||
}
|
||||
];
|
||||
Loading…
Reference in New Issue