Since there is no existing installed base, we can consolidate all migrations into a single complete schema file plus the migrations table initialization. This simplifies the database setup for new installations.
109 lines
3.5 KiB
SQL
109 lines
3.5 KiB
SQL
-- Complete schema for upaas (consolidated)
|
|
-- This represents the final state of all migrations applied
|
|
|
|
-- Users table (single admin user)
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id INTEGER PRIMARY KEY,
|
|
username TEXT UNIQUE NOT NULL,
|
|
password_hash TEXT NOT NULL,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Apps table
|
|
CREATE TABLE IF NOT EXISTS apps (
|
|
id TEXT PRIMARY KEY,
|
|
name TEXT UNIQUE NOT NULL,
|
|
repo_url TEXT NOT NULL,
|
|
branch TEXT NOT NULL DEFAULT 'main',
|
|
dockerfile_path TEXT DEFAULT 'Dockerfile',
|
|
webhook_secret TEXT NOT NULL,
|
|
ssh_private_key TEXT NOT NULL,
|
|
ssh_public_key TEXT NOT NULL,
|
|
image_id TEXT,
|
|
previous_image_id TEXT,
|
|
status TEXT DEFAULT 'pending',
|
|
docker_network TEXT,
|
|
ntfy_topic TEXT,
|
|
slack_webhook TEXT,
|
|
webhook_secret_hash TEXT NOT NULL DEFAULT '',
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- App environment variables
|
|
CREATE TABLE IF NOT EXISTS app_env_vars (
|
|
id INTEGER PRIMARY KEY,
|
|
app_id TEXT NOT NULL REFERENCES apps(id) ON DELETE CASCADE,
|
|
key TEXT NOT NULL,
|
|
value TEXT NOT NULL,
|
|
UNIQUE(app_id, key)
|
|
);
|
|
|
|
-- App labels
|
|
CREATE TABLE IF NOT EXISTS app_labels (
|
|
id INTEGER PRIMARY KEY,
|
|
app_id TEXT NOT NULL REFERENCES apps(id) ON DELETE CASCADE,
|
|
key TEXT NOT NULL,
|
|
value TEXT NOT NULL,
|
|
UNIQUE(app_id, key)
|
|
);
|
|
|
|
-- App volume mounts
|
|
CREATE TABLE IF NOT EXISTS app_volumes (
|
|
id INTEGER PRIMARY KEY,
|
|
app_id TEXT NOT NULL REFERENCES apps(id) ON DELETE CASCADE,
|
|
host_path TEXT NOT NULL,
|
|
container_path TEXT NOT NULL,
|
|
readonly INTEGER DEFAULT 0
|
|
);
|
|
|
|
-- App port mappings
|
|
CREATE TABLE IF NOT EXISTS app_ports (
|
|
id INTEGER PRIMARY KEY,
|
|
app_id TEXT NOT NULL REFERENCES apps(id) ON DELETE CASCADE,
|
|
host_port INTEGER NOT NULL,
|
|
container_port INTEGER NOT NULL,
|
|
protocol TEXT NOT NULL DEFAULT 'tcp' CHECK(protocol IN ('tcp', 'udp')),
|
|
UNIQUE(host_port, protocol)
|
|
);
|
|
|
|
-- Webhook events log
|
|
CREATE TABLE IF NOT EXISTS webhook_events (
|
|
id INTEGER PRIMARY KEY,
|
|
app_id TEXT NOT NULL REFERENCES apps(id) ON DELETE CASCADE,
|
|
event_type TEXT NOT NULL,
|
|
branch TEXT NOT NULL,
|
|
commit_sha TEXT,
|
|
commit_url TEXT,
|
|
payload TEXT,
|
|
matched INTEGER NOT NULL,
|
|
processed INTEGER DEFAULT 0,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Deployments log
|
|
CREATE TABLE IF NOT EXISTS deployments (
|
|
id INTEGER PRIMARY KEY,
|
|
app_id TEXT NOT NULL REFERENCES apps(id) ON DELETE CASCADE,
|
|
webhook_event_id INTEGER REFERENCES webhook_events(id),
|
|
commit_sha TEXT,
|
|
commit_url TEXT,
|
|
image_id TEXT,
|
|
status TEXT NOT NULL,
|
|
logs TEXT,
|
|
started_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
finished_at DATETIME
|
|
);
|
|
|
|
-- Indexes
|
|
CREATE INDEX IF NOT EXISTS idx_apps_status ON apps(status);
|
|
CREATE INDEX IF NOT EXISTS idx_apps_webhook_secret ON apps(webhook_secret);
|
|
CREATE INDEX IF NOT EXISTS idx_apps_webhook_secret_hash ON apps(webhook_secret_hash);
|
|
CREATE INDEX IF NOT EXISTS idx_app_env_vars_app_id ON app_env_vars(app_id);
|
|
CREATE INDEX IF NOT EXISTS idx_app_labels_app_id ON app_labels(app_id);
|
|
CREATE INDEX IF NOT EXISTS idx_app_volumes_app_id ON app_volumes(app_id);
|
|
CREATE INDEX IF NOT EXISTS idx_app_ports_app_id ON app_ports(app_id);
|
|
CREATE INDEX IF NOT EXISTS idx_webhook_events_app_id ON webhook_events(app_id);
|
|
CREATE INDEX IF NOT EXISTS idx_webhook_events_created_at ON webhook_events(created_at);
|
|
CREATE INDEX IF NOT EXISTS idx_deployments_app_id ON deployments(app_id);
|
|
CREATE INDEX IF NOT EXISTS idx_deployments_started_at ON deployments(started_at); |