-- Enable foreign keys for SQLite PRAGMA foreign_keys = ON; -- Users table CREATE TABLE users ( id INTEGER PRIMARY KEY AUTOINCREMENT, email TEXT UNIQUE NOT NULL, name TEXT NOT NULL, oauth_provider TEXT NOT NULL, oauth_id TEXT NOT NULL, password_hash TEXT, is_admin INTEGER NOT NULL DEFAULT 0, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, UNIQUE(oauth_provider, oauth_id) ); -- Runner API keys table CREATE TABLE runner_api_keys ( id INTEGER PRIMARY KEY AUTOINCREMENT, key_prefix TEXT NOT NULL, key_hash TEXT NOT NULL, name TEXT NOT NULL, description TEXT, scope TEXT NOT NULL DEFAULT 'user', is_active INTEGER NOT NULL DEFAULT 1, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, created_by INTEGER, FOREIGN KEY (created_by) REFERENCES users(id), UNIQUE(key_prefix) ); -- Jobs table CREATE TABLE jobs ( id INTEGER PRIMARY KEY AUTOINCREMENT, user_id INTEGER NOT NULL, job_type TEXT NOT NULL DEFAULT 'render', name TEXT NOT NULL, status TEXT NOT NULL DEFAULT 'pending', progress REAL NOT NULL DEFAULT 0.0, frame_start INTEGER, frame_end INTEGER, output_format TEXT, blend_metadata TEXT, retry_count INTEGER NOT NULL DEFAULT 0, max_retries INTEGER NOT NULL DEFAULT 3, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, started_at TIMESTAMP, completed_at TIMESTAMP, error_message TEXT, assigned_runner_id INTEGER, FOREIGN KEY (user_id) REFERENCES users(id) ); -- Runners table CREATE TABLE runners ( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL, hostname TEXT NOT NULL, ip_address TEXT NOT NULL, status TEXT NOT NULL DEFAULT 'offline', last_heartbeat TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, capabilities TEXT, api_key_id INTEGER, api_key_scope TEXT NOT NULL DEFAULT 'user', priority INTEGER NOT NULL DEFAULT 100, fingerprint TEXT, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (api_key_id) REFERENCES runner_api_keys(id) ); -- Tasks table CREATE TABLE tasks ( id INTEGER PRIMARY KEY AUTOINCREMENT, job_id INTEGER NOT NULL, runner_id INTEGER, frame INTEGER NOT NULL, status TEXT NOT NULL DEFAULT 'pending', output_path TEXT, task_type TEXT NOT NULL DEFAULT 'render', current_step TEXT, retry_count INTEGER NOT NULL DEFAULT 0, max_retries INTEGER NOT NULL DEFAULT 3, runner_failure_count INTEGER NOT NULL DEFAULT 0, timeout_seconds INTEGER, condition TEXT, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, started_at TIMESTAMP, completed_at TIMESTAMP, error_message TEXT, FOREIGN KEY (job_id) REFERENCES jobs(id), FOREIGN KEY (runner_id) REFERENCES runners(id) ); -- Job files table CREATE TABLE job_files ( id INTEGER PRIMARY KEY AUTOINCREMENT, job_id INTEGER NOT NULL, file_type TEXT NOT NULL, file_path TEXT NOT NULL, file_name TEXT NOT NULL, file_size INTEGER NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (job_id) REFERENCES jobs(id) ); -- Manager secrets table CREATE TABLE manager_secrets ( id INTEGER PRIMARY KEY AUTOINCREMENT, secret TEXT UNIQUE NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); -- Task logs table CREATE TABLE task_logs ( id INTEGER PRIMARY KEY AUTOINCREMENT, task_id INTEGER NOT NULL, runner_id INTEGER, log_level TEXT NOT NULL, message TEXT NOT NULL, step_name TEXT, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (task_id) REFERENCES tasks(id), FOREIGN KEY (runner_id) REFERENCES runners(id) ); -- Task steps table CREATE TABLE task_steps ( id INTEGER PRIMARY KEY AUTOINCREMENT, task_id INTEGER NOT NULL, step_name TEXT NOT NULL, status TEXT NOT NULL DEFAULT 'pending', started_at TIMESTAMP, completed_at TIMESTAMP, duration_ms INTEGER, error_message TEXT, FOREIGN KEY (task_id) REFERENCES tasks(id) ); -- Settings table CREATE TABLE settings ( key TEXT PRIMARY KEY, value TEXT NOT NULL, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); -- Sessions table CREATE TABLE sessions ( id INTEGER PRIMARY KEY AUTOINCREMENT, session_id TEXT UNIQUE NOT NULL, user_id INTEGER NOT NULL, email TEXT NOT NULL, name TEXT NOT NULL, is_admin INTEGER NOT NULL DEFAULT 0, expires_at TIMESTAMP NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (user_id) REFERENCES users(id) ); -- Indexes CREATE INDEX idx_jobs_user_id ON jobs(user_id); CREATE INDEX idx_jobs_status ON jobs(status); CREATE INDEX idx_jobs_user_status_created ON jobs(user_id, status, created_at DESC); CREATE INDEX idx_tasks_job_id ON tasks(job_id); CREATE INDEX idx_tasks_runner_id ON tasks(runner_id); CREATE INDEX idx_tasks_status ON tasks(status); CREATE INDEX idx_tasks_job_status ON tasks(job_id, status); CREATE INDEX idx_tasks_started_at ON tasks(started_at); CREATE INDEX idx_job_files_job_id ON job_files(job_id); CREATE INDEX idx_runner_api_keys_prefix ON runner_api_keys(key_prefix); CREATE INDEX idx_runner_api_keys_active ON runner_api_keys(is_active); CREATE INDEX idx_runner_api_keys_created_by ON runner_api_keys(created_by); CREATE INDEX idx_runners_api_key_id ON runners(api_key_id); CREATE INDEX idx_task_logs_task_id_created_at ON task_logs(task_id, created_at); CREATE INDEX idx_task_logs_task_id_id ON task_logs(task_id, id DESC); CREATE INDEX idx_task_logs_runner_id ON task_logs(runner_id); CREATE INDEX idx_task_steps_task_id ON task_steps(task_id); CREATE INDEX idx_runners_last_heartbeat ON runners(last_heartbeat); CREATE INDEX idx_sessions_session_id ON sessions(session_id); CREATE INDEX idx_sessions_user_id ON sessions(user_id); CREATE INDEX idx_sessions_expires_at ON sessions(expires_at); -- Initialize registration_enabled setting INSERT INTO settings (key, value, updated_at) VALUES ('registration_enabled', 'true', CURRENT_TIMESTAMP);