From 2216dd91a0ea5146ec18d772e9681749daaa1ac3 Mon Sep 17 00:00:00 2001 From: Simon Ser Date: Wed, 6 Dec 2023 11:39:46 +0100 Subject: [PATCH] database: move schema into separate file --- database/postgres.go | 116 +------------------------------ database/postgres_schema.sql | 111 +++++++++++++++++++++++++++++ database/sqlite.go | 131 +---------------------------------- database/sqlite_schema.sql | 126 +++++++++++++++++++++++++++++++++ 4 files changed, 243 insertions(+), 241 deletions(-) create mode 100644 database/postgres_schema.sql create mode 100644 database/sqlite_schema.sql diff --git a/database/postgres.go b/database/postgres.go index ca6bf51..c401119 100644 --- a/database/postgres.go +++ b/database/postgres.go @@ -3,6 +3,7 @@ package database import ( "context" "database/sql" + _ "embed" "errors" "fmt" "math" @@ -26,119 +27,8 @@ CREATE TABLE IF NOT EXISTS "Config" ( ); ` -const postgresSchema = ` -CREATE TABLE "User" ( - id SERIAL PRIMARY KEY, - username VARCHAR(255) NOT NULL UNIQUE, - password VARCHAR(255), - admin BOOLEAN NOT NULL DEFAULT FALSE, - nick VARCHAR(255), - realname VARCHAR(255), - created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), - enabled BOOLEAN NOT NULL DEFAULT TRUE, - downstream_interacted_at TIMESTAMP WITH TIME ZONE -); - -CREATE TYPE sasl_mechanism AS ENUM ('PLAIN', 'EXTERNAL'); - -CREATE TABLE "Network" ( - id SERIAL PRIMARY KEY, - name VARCHAR(255), - "user" INTEGER NOT NULL REFERENCES "User"(id) ON DELETE CASCADE, - addr VARCHAR(255) NOT NULL, - nick VARCHAR(255), - username VARCHAR(255), - realname VARCHAR(255), - certfp TEXT, - pass VARCHAR(255), - connect_commands VARCHAR(1023), - sasl_mechanism sasl_mechanism, - sasl_plain_username VARCHAR(255), - sasl_plain_password VARCHAR(255), - sasl_external_cert BYTEA, - sasl_external_key BYTEA, - auto_away BOOLEAN NOT NULL DEFAULT TRUE, - enabled BOOLEAN NOT NULL DEFAULT TRUE, - UNIQUE("user", addr, nick), - UNIQUE("user", name) -); - -CREATE TABLE "Channel" ( - id SERIAL PRIMARY KEY, - network INTEGER NOT NULL REFERENCES "Network"(id) ON DELETE CASCADE, - name VARCHAR(255) NOT NULL, - key VARCHAR(255), - detached BOOLEAN NOT NULL DEFAULT FALSE, - detached_internal_msgid VARCHAR(255), - relay_detached INTEGER NOT NULL DEFAULT 0, - reattach_on INTEGER NOT NULL DEFAULT 0, - detach_after INTEGER NOT NULL DEFAULT 0, - detach_on INTEGER NOT NULL DEFAULT 0, - UNIQUE(network, name) -); - -CREATE TABLE "DeliveryReceipt" ( - id SERIAL PRIMARY KEY, - network INTEGER NOT NULL REFERENCES "Network"(id) ON DELETE CASCADE, - target VARCHAR(255) NOT NULL, - client VARCHAR(255) NOT NULL DEFAULT '', - internal_msgid VARCHAR(255) NOT NULL, - UNIQUE(network, target, client) -); - -CREATE TABLE "ReadReceipt" ( - id SERIAL PRIMARY KEY, - network INTEGER NOT NULL REFERENCES "Network"(id) ON DELETE CASCADE, - target VARCHAR(255) NOT NULL, - timestamp TIMESTAMP WITH TIME ZONE NOT NULL, - UNIQUE(network, target) -); - -CREATE TABLE "WebPushConfig" ( - id SERIAL PRIMARY KEY, - created_at TIMESTAMP WITH TIME ZONE NOT NULL, - vapid_key_public TEXT NOT NULL, - vapid_key_private TEXT NOT NULL, - UNIQUE(vapid_key_public) -); - -CREATE TABLE "WebPushSubscription" ( - id SERIAL PRIMARY KEY, - created_at TIMESTAMP WITH TIME ZONE NOT NULL, - updated_at TIMESTAMP WITH TIME ZONE NOT NULL, - "user" INTEGER NOT NULL REFERENCES "User"(id) ON DELETE CASCADE, - network INTEGER REFERENCES "Network"(id) ON DELETE CASCADE, - endpoint TEXT NOT NULL, - key_vapid TEXT, - key_auth TEXT, - key_p256dh TEXT, - UNIQUE(network, endpoint) -); - -CREATE TABLE "MessageTarget" ( - id SERIAL PRIMARY KEY, - network INTEGER NOT NULL REFERENCES "Network"(id) ON DELETE CASCADE, - target TEXT NOT NULL, - UNIQUE(network, target) -); - -CREATE TEXT SEARCH DICTIONARY search_simple_dictionary ( - TEMPLATE = pg_catalog.simple -); -CREATE TEXT SEARCH CONFIGURATION @SCHEMA_PREFIX@search_simple ( COPY = pg_catalog.simple ); -ALTER TEXT SEARCH CONFIGURATION @SCHEMA_PREFIX@search_simple ALTER MAPPING FOR asciiword, asciihword, hword_asciipart, hword, hword_part, word WITH @SCHEMA_PREFIX@search_simple_dictionary; -CREATE TABLE "Message" ( - id SERIAL PRIMARY KEY, - target INTEGER NOT NULL REFERENCES "MessageTarget"(id) ON DELETE CASCADE, - raw TEXT NOT NULL, - time TIMESTAMP WITH TIME ZONE NOT NULL, - sender TEXT NOT NULL, - text TEXT, - text_search tsvector GENERATED ALWAYS AS (to_tsvector('@SCHEMA_PREFIX@search_simple', text)) STORED -); -CREATE INDEX "MessageIndex" ON "Message" (target, time); -CREATE INDEX "MessageSearchIndex" ON "Message" USING GIN (text_search); -` +//go:embed postgres_schema.sql +var postgresSchema string var postgresMigrations = []string{ "", // migration #0 is reserved for schema initialization diff --git a/database/postgres_schema.sql b/database/postgres_schema.sql new file mode 100644 index 0000000..9643bb7 --- /dev/null +++ b/database/postgres_schema.sql @@ -0,0 +1,111 @@ +CREATE TABLE "User" ( + id SERIAL PRIMARY KEY, + username VARCHAR(255) NOT NULL UNIQUE, + password VARCHAR(255), + admin BOOLEAN NOT NULL DEFAULT FALSE, + nick VARCHAR(255), + realname VARCHAR(255), + created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), + enabled BOOLEAN NOT NULL DEFAULT TRUE, + downstream_interacted_at TIMESTAMP WITH TIME ZONE +); + +CREATE TYPE sasl_mechanism AS ENUM ('PLAIN', 'EXTERNAL'); + +CREATE TABLE "Network" ( + id SERIAL PRIMARY KEY, + name VARCHAR(255), + "user" INTEGER NOT NULL REFERENCES "User"(id) ON DELETE CASCADE, + addr VARCHAR(255) NOT NULL, + nick VARCHAR(255), + username VARCHAR(255), + realname VARCHAR(255), + certfp TEXT, + pass VARCHAR(255), + connect_commands VARCHAR(1023), + sasl_mechanism sasl_mechanism, + sasl_plain_username VARCHAR(255), + sasl_plain_password VARCHAR(255), + sasl_external_cert BYTEA, + sasl_external_key BYTEA, + auto_away BOOLEAN NOT NULL DEFAULT TRUE, + enabled BOOLEAN NOT NULL DEFAULT TRUE, + UNIQUE("user", addr, nick), + UNIQUE("user", name) +); + +CREATE TABLE "Channel" ( + id SERIAL PRIMARY KEY, + network INTEGER NOT NULL REFERENCES "Network"(id) ON DELETE CASCADE, + name VARCHAR(255) NOT NULL, + key VARCHAR(255), + detached BOOLEAN NOT NULL DEFAULT FALSE, + detached_internal_msgid VARCHAR(255), + relay_detached INTEGER NOT NULL DEFAULT 0, + reattach_on INTEGER NOT NULL DEFAULT 0, + detach_after INTEGER NOT NULL DEFAULT 0, + detach_on INTEGER NOT NULL DEFAULT 0, + UNIQUE(network, name) +); + +CREATE TABLE "DeliveryReceipt" ( + id SERIAL PRIMARY KEY, + network INTEGER NOT NULL REFERENCES "Network"(id) ON DELETE CASCADE, + target VARCHAR(255) NOT NULL, + client VARCHAR(255) NOT NULL DEFAULT '', + internal_msgid VARCHAR(255) NOT NULL, + UNIQUE(network, target, client) +); + +CREATE TABLE "ReadReceipt" ( + id SERIAL PRIMARY KEY, + network INTEGER NOT NULL REFERENCES "Network"(id) ON DELETE CASCADE, + target VARCHAR(255) NOT NULL, + timestamp TIMESTAMP WITH TIME ZONE NOT NULL, + UNIQUE(network, target) +); + +CREATE TABLE "WebPushConfig" ( + id SERIAL PRIMARY KEY, + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + vapid_key_public TEXT NOT NULL, + vapid_key_private TEXT NOT NULL, + UNIQUE(vapid_key_public) +); + +CREATE TABLE "WebPushSubscription" ( + id SERIAL PRIMARY KEY, + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + updated_at TIMESTAMP WITH TIME ZONE NOT NULL, + "user" INTEGER NOT NULL REFERENCES "User"(id) ON DELETE CASCADE, + network INTEGER REFERENCES "Network"(id) ON DELETE CASCADE, + endpoint TEXT NOT NULL, + key_vapid TEXT, + key_auth TEXT, + key_p256dh TEXT, + UNIQUE(network, endpoint) +); + +CREATE TABLE "MessageTarget" ( + id SERIAL PRIMARY KEY, + network INTEGER NOT NULL REFERENCES "Network"(id) ON DELETE CASCADE, + target TEXT NOT NULL, + UNIQUE(network, target) +); + +CREATE TEXT SEARCH DICTIONARY search_simple_dictionary ( + TEMPLATE = pg_catalog.simple +); +CREATE TEXT SEARCH CONFIGURATION @SCHEMA_PREFIX@search_simple ( COPY = pg_catalog.simple ); +ALTER TEXT SEARCH CONFIGURATION @SCHEMA_PREFIX@search_simple ALTER MAPPING FOR asciiword, asciihword, hword_asciipart, hword, hword_part, word WITH @SCHEMA_PREFIX@search_simple_dictionary; +CREATE TABLE "Message" ( + id SERIAL PRIMARY KEY, + target INTEGER NOT NULL REFERENCES "MessageTarget"(id) ON DELETE CASCADE, + raw TEXT NOT NULL, + time TIMESTAMP WITH TIME ZONE NOT NULL, + sender TEXT NOT NULL, + text TEXT, + text_search tsvector GENERATED ALWAYS AS (to_tsvector('@SCHEMA_PREFIX@search_simple', text)) STORED +); +CREATE INDEX "MessageIndex" ON "Message" (target, time); +CREATE INDEX "MessageSearchIndex" ON "Message" USING GIN (text_search); diff --git a/database/sqlite.go b/database/sqlite.go index 97ce8fa..f251f03 100644 --- a/database/sqlite.go +++ b/database/sqlite.go @@ -6,6 +6,7 @@ import ( "context" "database/sql" sqldriver "database/sql/driver" + _ "embed" "fmt" "math" "strings" @@ -57,134 +58,8 @@ func (t sqliteTime) Value() (sqldriver.Value, error) { return t.UTC().Format(sqliteTimeLayout), nil } -const sqliteSchema = ` -CREATE TABLE User ( - id INTEGER PRIMARY KEY, - username TEXT NOT NULL UNIQUE, - password TEXT, - admin INTEGER NOT NULL DEFAULT 0, - realname TEXT, - nick TEXT, - created_at TEXT NOT NULL, - enabled INTEGER NOT NULL DEFAULT 1, - downstream_interacted_at TEXT -); - -CREATE TABLE Network ( - id INTEGER PRIMARY KEY, - name TEXT, - user INTEGER NOT NULL, - addr TEXT NOT NULL, - nick TEXT, - username TEXT, - realname TEXT, - certfp TEXT, - pass TEXT, - connect_commands TEXT, - sasl_mechanism TEXT, - sasl_plain_username TEXT, - sasl_plain_password TEXT, - sasl_external_cert BLOB, - sasl_external_key BLOB, - auto_away INTEGER NOT NULL DEFAULT 1, - enabled INTEGER NOT NULL DEFAULT 1, - FOREIGN KEY(user) REFERENCES User(id), - UNIQUE(user, addr, nick), - UNIQUE(user, name) -); - -CREATE TABLE Channel ( - id INTEGER PRIMARY KEY, - network INTEGER NOT NULL, - name TEXT NOT NULL, - key TEXT, - detached INTEGER NOT NULL DEFAULT 0, - detached_internal_msgid TEXT, - relay_detached INTEGER NOT NULL DEFAULT 0, - reattach_on INTEGER NOT NULL DEFAULT 0, - detach_after INTEGER NOT NULL DEFAULT 0, - detach_on INTEGER NOT NULL DEFAULT 0, - FOREIGN KEY(network) REFERENCES Network(id), - UNIQUE(network, name) -); - -CREATE TABLE DeliveryReceipt ( - id INTEGER PRIMARY KEY, - network INTEGER NOT NULL, - target TEXT NOT NULL, - client TEXT, - internal_msgid TEXT NOT NULL, - FOREIGN KEY(network) REFERENCES Network(id), - UNIQUE(network, target, client) -); - -CREATE TABLE ReadReceipt ( - id INTEGER PRIMARY KEY, - network INTEGER NOT NULL, - target TEXT NOT NULL, - timestamp TEXT NOT NULL, - FOREIGN KEY(network) REFERENCES Network(id), - UNIQUE(network, target) -); - -CREATE TABLE WebPushConfig ( - id INTEGER PRIMARY KEY, - created_at TEXT NOT NULL, - vapid_key_public TEXT NOT NULL, - vapid_key_private TEXT NOT NULL, - UNIQUE(vapid_key_public) -); - -CREATE TABLE WebPushSubscription ( - id INTEGER PRIMARY KEY, - created_at TEXT NOT NULL, - updated_at TEXT NOT NULL, - user INTEGER NOT NULL, - network INTEGER, - endpoint TEXT NOT NULL, - key_vapid TEXT, - key_auth TEXT, - key_p256dh TEXT, - FOREIGN KEY(user) REFERENCES User(id), - FOREIGN KEY(network) REFERENCES Network(id), - UNIQUE(network, endpoint) -); - -CREATE TABLE Message ( - id INTEGER PRIMARY KEY, - target INTEGER NOT NULL, - raw TEXT NOT NULL, - time TEXT NOT NULL, - sender TEXT NOT NULL, - text TEXT, - FOREIGN KEY(target) REFERENCES MessageTarget(id) -); -CREATE INDEX MessageIndex ON Message(target, time); - -CREATE TABLE MessageTarget ( - id INTEGER PRIMARY KEY, - network INTEGER NOT NULL, - target TEXT NOT NULL, - FOREIGN KEY(network) REFERENCES Network(id), - UNIQUE(network, target) -); - -CREATE VIRTUAL TABLE MessageFTS USING fts5 ( - text, - content=Message, - content_rowid=id -); -CREATE TRIGGER MessageFTSInsert AFTER INSERT ON Message BEGIN - INSERT INTO MessageFTS(rowid, text) VALUES (new.id, new.text); -END; -CREATE TRIGGER MessageFTSDelete AFTER DELETE ON Message BEGIN - INSERT INTO MessageFTS(MessageFTS, rowid, text) VALUES ('delete', old.id, old.text); -END; -CREATE TRIGGER MessageFTSUpdate AFTER UPDATE ON Message BEGIN - INSERT INTO MessageFTS(MessageFTS, rowid, text) VALUES ('delete', old.id, old.text); - INSERT INTO MessageFTS(rowid, text) VALUES (new.id, new.text); -END; -` +//go:embed sqlite_schema.sql +var sqliteSchema string var sqliteMigrations = []string{ "", // migration #0 is reserved for schema initialization diff --git a/database/sqlite_schema.sql b/database/sqlite_schema.sql new file mode 100644 index 0000000..b8445d1 --- /dev/null +++ b/database/sqlite_schema.sql @@ -0,0 +1,126 @@ +CREATE TABLE User ( + id INTEGER PRIMARY KEY, + username TEXT NOT NULL UNIQUE, + password TEXT, + admin INTEGER NOT NULL DEFAULT 0, + realname TEXT, + nick TEXT, + created_at TEXT NOT NULL, + enabled INTEGER NOT NULL DEFAULT 1, + downstream_interacted_at TEXT +); + +CREATE TABLE Network ( + id INTEGER PRIMARY KEY, + name TEXT, + user INTEGER NOT NULL, + addr TEXT NOT NULL, + nick TEXT, + username TEXT, + realname TEXT, + certfp TEXT, + pass TEXT, + connect_commands TEXT, + sasl_mechanism TEXT, + sasl_plain_username TEXT, + sasl_plain_password TEXT, + sasl_external_cert BLOB, + sasl_external_key BLOB, + auto_away INTEGER NOT NULL DEFAULT 1, + enabled INTEGER NOT NULL DEFAULT 1, + FOREIGN KEY(user) REFERENCES User(id), + UNIQUE(user, addr, nick), + UNIQUE(user, name) +); + +CREATE TABLE Channel ( + id INTEGER PRIMARY KEY, + network INTEGER NOT NULL, + name TEXT NOT NULL, + key TEXT, + detached INTEGER NOT NULL DEFAULT 0, + detached_internal_msgid TEXT, + relay_detached INTEGER NOT NULL DEFAULT 0, + reattach_on INTEGER NOT NULL DEFAULT 0, + detach_after INTEGER NOT NULL DEFAULT 0, + detach_on INTEGER NOT NULL DEFAULT 0, + FOREIGN KEY(network) REFERENCES Network(id), + UNIQUE(network, name) +); + +CREATE TABLE DeliveryReceipt ( + id INTEGER PRIMARY KEY, + network INTEGER NOT NULL, + target TEXT NOT NULL, + client TEXT, + internal_msgid TEXT NOT NULL, + FOREIGN KEY(network) REFERENCES Network(id), + UNIQUE(network, target, client) +); + +CREATE TABLE ReadReceipt ( + id INTEGER PRIMARY KEY, + network INTEGER NOT NULL, + target TEXT NOT NULL, + timestamp TEXT NOT NULL, + FOREIGN KEY(network) REFERENCES Network(id), + UNIQUE(network, target) +); + +CREATE TABLE WebPushConfig ( + id INTEGER PRIMARY KEY, + created_at TEXT NOT NULL, + vapid_key_public TEXT NOT NULL, + vapid_key_private TEXT NOT NULL, + UNIQUE(vapid_key_public) +); + +CREATE TABLE WebPushSubscription ( + id INTEGER PRIMARY KEY, + created_at TEXT NOT NULL, + updated_at TEXT NOT NULL, + user INTEGER NOT NULL, + network INTEGER, + endpoint TEXT NOT NULL, + key_vapid TEXT, + key_auth TEXT, + key_p256dh TEXT, + FOREIGN KEY(user) REFERENCES User(id), + FOREIGN KEY(network) REFERENCES Network(id), + UNIQUE(network, endpoint) +); + +CREATE TABLE Message ( + id INTEGER PRIMARY KEY, + target INTEGER NOT NULL, + raw TEXT NOT NULL, + time TEXT NOT NULL, + sender TEXT NOT NULL, + text TEXT, + FOREIGN KEY(target) REFERENCES MessageTarget(id) +); +CREATE INDEX MessageIndex ON Message(target, time); + +CREATE TABLE MessageTarget ( + id INTEGER PRIMARY KEY, + network INTEGER NOT NULL, + target TEXT NOT NULL, + FOREIGN KEY(network) REFERENCES Network(id), + UNIQUE(network, target) +); + +CREATE VIRTUAL TABLE MessageFTS USING fts5 ( + text, + content=Message, + content_rowid=id +); +CREATE TRIGGER MessageFTSInsert AFTER INSERT ON Message BEGIN + INSERT INTO MessageFTS(rowid, text) VALUES (new.id, new.text); +END; +CREATE TRIGGER MessageFTSDelete AFTER DELETE ON Message BEGIN + INSERT INTO MessageFTS(MessageFTS, rowid, text) VALUES ('delete', old.id, old.text); +END; +CREATE TRIGGER MessageFTSUpdate AFTER UPDATE ON Message BEGIN + INSERT INTO MessageFTS(MessageFTS, rowid, text) VALUES ('delete', old.id, old.text); + INSERT INTO MessageFTS(rowid, text) VALUES (new.id, new.text); +END;