69 lines
2.9 KiB
SQL
69 lines
2.9 KiB
SQL
-- migrations/001_init_tables.sqlite.sql
|
|
-- SQLite-compatible rewrite of migrations/001_init_tables.sql
|
|
PRAGMA foreign_keys = ON;
|
|
|
|
-- Table: lists
|
|
CREATE TABLE IF NOT EXISTS lists (
|
|
id TEXT PRIMARY KEY NOT NULL,
|
|
name TEXT NOT NULL CHECK (length(trim(name)) > 0 AND length(name) <= 24),
|
|
owner_id TEXT NOT NULL,
|
|
private INTEGER NOT NULL DEFAULT 1, -- 0 = false, 1 = true
|
|
created_at DATETIME NOT NULL DEFAULT (CURRENT_TIMESTAMP),
|
|
updated_at DATETIME NOT NULL DEFAULT (CURRENT_TIMESTAMP)
|
|
);
|
|
|
|
-- Trigger to keep updated_at current.
|
|
-- Uses an AFTER UPDATE that only performs the extra UPDATE when the client
|
|
-- didn't explicitly change updated_at; the inner UPDATE won't recurse
|
|
-- because the WHEN clause will be false on the second invocation.
|
|
CREATE TRIGGER IF NOT EXISTS trg_lists_updated_at
|
|
AFTER UPDATE ON lists
|
|
FOR EACH ROW
|
|
WHEN NEW.updated_at = OLD.updated_at
|
|
BEGIN
|
|
UPDATE lists SET updated_at = CURRENT_TIMESTAMP WHERE id = OLD.id;
|
|
END;
|
|
|
|
-- Index to quickly find lists by owner
|
|
CREATE INDEX IF NOT EXISTS idx_lists_owner_id ON lists(owner_id);
|
|
|
|
-- Table: guilds
|
|
CREATE TABLE IF NOT EXISTS guilds (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
guild_id TEXT NOT NULL,
|
|
list_id TEXT NOT NULL REFERENCES lists(id) ON DELETE CASCADE,
|
|
auto_add INTEGER NOT NULL DEFAULT 1, -- 0 = false, 1 = true
|
|
auto_remove INTEGER NOT NULL DEFAULT 0, -- 0 = false, 1 = true
|
|
created_at DATETIME NOT NULL DEFAULT (CURRENT_TIMESTAMP)
|
|
);
|
|
|
|
-- Table: Bans
|
|
CREATE TABLE IF NOT EXISTS bans (
|
|
id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))),
|
|
user_id TEXT NOT NULL,
|
|
reason TEXT,
|
|
list_id TEXT NOT NULL REFERENCES lists(id) ON DELETE CASCADE,
|
|
banned_by TEXT NOT NULL,
|
|
banned_at DATETIME NOT NULL DEFAULT (CURRENT_TIMESTAMP)
|
|
);
|
|
|
|
-- Table: Perms (Users/Guilds with write access to a list that aren't the owner)
|
|
CREATE TABLE IF NOT EXISTS perms (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
list_id TEXT NOT NULL REFERENCES lists(id) ON DELETE CASCADE,
|
|
entity_id TEXT NOT NULL, -- user id or guild id
|
|
entity_type TEXT NOT NULL CHECK (entity_type IN ('user', 'guild')),
|
|
auto_add INTEGER NOT NULL DEFAULT 0, -- 0 = false, 1 = true; Whether this entitys bans should be auto-added to the list (only for guilds)
|
|
auto_remove INTEGER NOT NULL DEFAULT 0, -- 0 = false, 1 = true; Whether this entitys unbans should be auto-removed from the list (only for guilds)
|
|
created_at DATETIME NOT NULL DEFAULT (CURRENT_TIMESTAMP)
|
|
);
|
|
|
|
-- Ensure a guild can't be attached to the same list twice
|
|
CREATE UNIQUE INDEX IF NOT EXISTS ux_guilds_guildid_listid ON guilds(guild_id, list_id);
|
|
|
|
-- Helpful index to look up guild rows by guild_id
|
|
CREATE INDEX IF NOT EXISTS idx_guilds_guild_id ON guilds(guild_id);
|
|
|
|
-- Example inserts
|
|
-- INSERT INTO lists (name, owner_id, private) VALUES ('Example List', 'owner123', 1);
|
|
-- INSERT INTO guilds (guild_id, list_id, auto_add) VALUES ('guild123', (SELECT id FROM lists WHERE name = 'Example List'), 1); |