99 lines
3.1 KiB
SQL
99 lines
3.1 KiB
SQL
CREATE TABLE users
|
|
(
|
|
_internal_id INTEGER UNIQUE NOT NULL PRIMARY KEY AUTOINCREMENT,
|
|
"telegram::user_id" INTEGER UNIQUE NOT NULL,
|
|
display_name TEXT NOT NULL
|
|
) STRICT;
|
|
|
|
CREATE TABLE chats
|
|
(
|
|
_internal_id INTEGER UNIQUE NOT NULL PRIMARY KEY AUTOINCREMENT,
|
|
"telegram::chat_id" INTEGER UNIQUE NOT NULL
|
|
) STRICT;
|
|
|
|
CREATE TABLE moderators
|
|
(
|
|
user INTEGER NOT NULL REFERENCES users (_internal_id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
chat INTEGER NOT NULL REFERENCES chats (_internal_id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
can_create_queues INTEGER NOT NULL DEFAULT FALSE,
|
|
can_finalize_queues INTEGER NOT NULL DEFAULT FALSE,
|
|
|
|
UNIQUE (user, chat)
|
|
) STRICT;
|
|
|
|
CREATE TABLE queue_sets
|
|
(
|
|
_internal_id INTEGER UNIQUE NOT NULL PRIMARY KEY AUTOINCREMENT,
|
|
chat INTEGER NOT NULL REFERENCES chats (_internal_id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
"telegram::message_id" INTEGER NOT NULL,
|
|
name TEXT NOT NULL,
|
|
is_open INTEGER NOT NULL DEFAULT TRUE,
|
|
|
|
UNIQUE (chat, "telegram::message_id")
|
|
) STRICT;
|
|
|
|
CREATE TABLE queues
|
|
(
|
|
_internal_id INTEGER UNIQUE NOT NULL PRIMARY KEY AUTOINCREMENT,
|
|
queue_set INTEGER NOT NULL REFERENCES queue_sets (_internal_id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
name TEXT NOT NULL,
|
|
ordinal INTEGER NOT NULL,
|
|
|
|
UNIQUE (queue_set, ordinal)
|
|
) STRICT;
|
|
|
|
|
|
CREATE TABLE "user->queue"
|
|
(
|
|
user INTEGER NOT NULL REFERENCES users (_internal_id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
queue_set INTEGER NOT NULL REFERENCES queue_sets (_internal_id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
queue INTEGER REFERENCES queues (_internal_id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
ordinal INTEGER NOT NULL CHECK ( ordinal >= 0 ),
|
|
|
|
UNIQUE (user, queue_set),
|
|
UNIQUE (queue_set, queue, ordinal)
|
|
) STRICT;
|
|
|
|
CREATE TRIGGER "user->queue::check_insert_queue_in_set"
|
|
BEFORE INSERT
|
|
ON "user->queue"
|
|
FOR EACH ROW
|
|
WHEN NEW.queue IS NOT NULL
|
|
BEGIN
|
|
SELECT CASE WHEN queues.queue_set != NEW.queue_set THEN raise(ABORT, 'Queue references another set') END
|
|
FROM queues
|
|
WHERE queues._internal_id = NEW.queue;
|
|
END;
|
|
|
|
CREATE TRIGGER "user->queue::check_insert_null_queue"
|
|
BEFORE INSERT
|
|
ON "user->queue"
|
|
FOR EACH ROW
|
|
WHEN NEW.queue IS NULL
|
|
BEGIN
|
|
SELECT CASE WHEN count() > 0 THEN raise(ABORT, 'Cant use NULL when set contains queues') END
|
|
FROM queues
|
|
WHERE queues.queue_set = NEW.queue_set;
|
|
END;
|
|
|
|
CREATE TRIGGER "user->queue::check_update_queue_in_set"
|
|
BEFORE UPDATE OF queue, queue_set
|
|
ON "user->queue"
|
|
FOR EACH ROW
|
|
WHEN NEW.queue IS NOT NULL
|
|
BEGIN
|
|
SELECT CASE WHEN queues.queue_set != NEW.queue_set THEN raise(ABORT, 'Queue references another set') END
|
|
FROM queues
|
|
WHERE queues._internal_id = NEW.queue;
|
|
END;
|
|
|
|
CREATE TRIGGER "user->queue::check_update_null_queue"
|
|
BEFORE UPDATE OF queue, queue_set
|
|
ON "user->queue"
|
|
FOR EACH ROW
|
|
WHEN NEW.queue IS NULL
|
|
BEGIN
|
|
SELECT CASE WHEN count() > 0 THEN raise(ABORT, 'Cant use NULL when set contains queues') END
|
|
FROM queues
|
|
WHERE queues.queue_set = NEW.queue_set;
|
|
END; |