Scenario generator for vore roleplay and story ideas. https://scenario-generator.deliciousreya.net/responses
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
vore-scenario-generator/migrations/0003_split_responses_table_...

422 lines
14 KiB

-- Migration number: 0003 2024-01-08T04:03:32.751Z
CREATE TABLE IF NOT EXISTS rollableResults
(
id INTEGER PRIMARY KEY,
tableId INTEGER NOT NULL, -- FOREIGN KEY REFERENCES rollableTables (id) ON UPDATE CASCADE ON DELETE CASCADE
text TEXT NOT NULL,
UNIQUE (tableId, text)
) STRICT;
CREATE TRIGGER IF NOT EXISTS rollableResultInsert
AFTER INSERT
ON rollableResults
FOR EACH ROW
WHEN NOT EXISTS (SELECT id
FROM rollableTables
WHERE id = NEW.tableId)
BEGIN
SELECT RAISE(ABORT, 'rollable table does not exist');
END;
CREATE TRIGGER IF NOT EXISTS rollableResultTableIdUpdate
AFTER UPDATE OF tableid
ON rollableResults
FOR EACH ROW
WHEN NOT EXISTS (SELECT id
FROM rollableTables
WHERE id = NEW.tableId)
BEGIN
SELECT RAISE(ABORT, 'rollable table does not exist');
END;
INSERT OR IGNORE INTO rollableResults (tableId, text)
SELECT DISTINCT responses.tableId, responses.text
FROM responses;
CREATE TABLE IF NOT EXISTS authorshipTypes
(
id INTEGER PRIMARY KEY,
name TEXT NOT NULL UNIQUE,
relationPrefix TEXT NOT NULL,
defaultAuthor TEXT NOT NULL
) STRICT;
INSERT INTO authorshipTypes (id, name, relationPrefix, defaultAuthor)
VALUES (0, 'Discord contributor', 'contributed by', 'an anonymous Discord user'),
(1, 'Web contributor', 'contributed by', 'an anonymous web user'),
(2, 'author', 'written by', 'an anonymous author'),
(3, 'source', 'from', 'an unknown source');
CREATE TABLE IF NOT EXISTS authors
(
id INTEGER PRIMARY KEY,
name TEXT,
url TEXT,
discordUsername TEXT,
discordSnowflake TEXT UNIQUE,
authorshipTypeId INTEGER NOT NULL,
-- FOREIGN KEY REFERENCES authorshipTypes(id) ON DELETE RESTRICT ON UPDATE CASCADE
CONSTRAINT onlyUrlIfNameIsGiven CHECK (NOT (name IS NULL AND url IS NOT NULL))
) STRICT;
CREATE TRIGGER IF NOT EXISTS authorInsert
AFTER INSERT
ON authors
FOR EACH ROW
WHEN NOT EXISTS (SELECT id
FROM authorshipTypes
WHERE id = NEW.authorshipTypeId)
BEGIN
SELECT RAISE(ABORT, 'authorship type does not exist');
END;
CREATE TRIGGER IF NOT EXISTS authorAuthorshipTypeIdUpdate
AFTER UPDATE OF authorshipTypeId
ON authors
FOR EACH ROW
WHEN NOT EXISTS (SELECT id
FROM authorshipTypes
WHERE id = NEW.authorshipTypeId)
BEGIN
SELECT RAISE(ABORT, 'authorship type does not exist');
END;
CREATE TRIGGER IF NOT EXISTS authorshipTypeIdUpdate
AFTER UPDATE OF id
ON authorshipTypes
FOR EACH ROW
BEGIN
UPDATE authors SET authorshipTypeId = NEW.id WHERE authorshipTypeId = OLD.id;
END;
CREATE TRIGGER IF NOT EXISTS authorshipTypeDeleted
AFTER DELETE
ON authorshipTypes
FOR EACH ROW
WHEN EXISTS (SELECT id
FROM authors
WHERE authorshipTypeId = OLD.id)
BEGIN
SELECT RAISE(ABORT, 'authorship type is still used1');
END;
INSERT OR IGNORE INTO authors (discordSnowflake, authorshipTypeId)
SELECT snowflake, 0
FROM (SELECT DISTINCT responses.userSnowflake as snowflake FROM responses);
CREATE TABLE IF NOT EXISTS resultSets
(
id INTEGER PRIMARY KEY,
name TEXT,
description TEXT,
creatorId INTEGER,
discordSnowflake TEXT,
global INTEGER NOT NULL DEFAULT FALSE CHECK (global IN (TRUE, FALSE))
) STRICT;
CREATE UNIQUE INDEX idx_resultSets_global ON resultSets (global, discordSnowflake);
INSERT OR IGNORE INTO resultSets (discordSnowflake, global)
SELECT DISTINCT COALESCE(responses.serverSnowflake, responses.userSnowflake) AS discordSnowflake,
responses.access = 0 AS global
FROM responses;
CREATE TABLE IF NOT EXISTS resultMappings
(
id INTEGER PRIMARY KEY,
resultId INTEGER NOT NULL, -- FOREIGN KEY REFERENCES rollableResults (id) ON DELETE CASCADE ON UPDATE CASCADE
setId INTEGER NOT NULL, -- FOREIGN KEY REFERENCES resultSets (id) ON DELETE CASCADE ON UPDATE CASCADE
authorId INTEGER, -- FOREIGN KEY REFERENCES authors (id) ON DELETE SET NULL ON UPDATE CASCADE
created INTEGER NOT NULL,
updated INTEGER NOT NULL
) STRICT;
CREATE UNIQUE INDEX IF NOT EXISTS idx_resultMapping_setId_resultId_resultOncePerSet ON resultMappings (setId, resultId);
INSERT OR IGNORE INTO resultMappings (resultId, setId, authorId, created, updated)
SELECT rollableResults.id, resultSets.id, authors.id, responses.id, responses.timestamp
FROM responses
LEFT JOIN rollableResults
ON rollableResults.tableId = responses.tableId
AND rollableResults.text = responses.text
LEFT JOIN resultSets
ON (responses.access = 2 AND
resultSets.discordSnowflake = responses.userSnowflake AND
resultSets.global = 0)
OR (responses.access = 1 AND
resultSets.discordSnowflake = responses.serverSnowflake AND
resultSets.global = 0)
OR (responses.access = 0 AND
resultSets.discordSnowflake = COALESCE(responses.serverSnowflake, responses.userSnowflake) AND
resultSets.global = 1)
LEFT JOIN authors
ON authors.discordSnowflake = responses.userSnowflake;
CREATE TRIGGER IF NOT EXISTS resultAuthorInsert
AFTER INSERT
ON resultMappings
FOR EACH ROW
WHEN NOT EXISTS (SELECT id
FROM rollableResults
WHERE id = NEW.resultId)
OR NOT EXISTS (SELECT id
FROM resultSets
WHERE id = NEW.setId)
OR NEW.authorId IS NOT NULL AND NOT EXISTS (SELECT id
FROM authors
WHERE id = NEW.authorId)
BEGIN
SELECT RAISE(ABORT, 'all of resultId, setId, authorId must exist if given');
END;
CREATE TRIGGER IF NOT EXISTS resultAuthorResultIdUpdate
AFTER UPDATE OF resultId
ON resultMappings
FOR EACH ROW
WHEN NOT EXISTS (SELECT id
FROM rollableResults
WHERE id = NEW.resultId)
BEGIN
SELECT RAISE(ABORT, 'result must exist');
END;
CREATE TRIGGER IF NOT EXISTS resultAuthorSetIdUpdate
AFTER UPDATE OF setId
ON resultMappings
FOR EACH ROW
WHEN NOT EXISTS (SELECT id
FROM resultSets
WHERE id = NEW.setId)
BEGIN
SELECT RAISE(ABORT, 'setId must exist');
END;
CREATE TRIGGER IF NOT EXISTS resultAuthorAuthorIdUpdate
AFTER UPDATE OF authorId
ON resultMappings
FOR EACH ROW
WHEN NEW.authorId IS NOT NULL AND NOT EXISTS (SELECT id
FROM authors
WHERE id = NEW.authorId)
BEGIN
SELECT RAISE(ABORT, 'author must exist if given');
END;
CREATE TRIGGER IF NOT EXISTS rollableResultIdUpdate
AFTER UPDATE OF id
ON rollableResults
FOR EACH ROW
BEGIN
UPDATE resultMappings SET resultId = NEW.id WHERE resultId = OLD.id;
END;
CREATE TRIGGER IF NOT EXISTS resultSetIdUpdate
AFTER UPDATE OF id
ON resultSets
FOR EACH ROW
BEGIN
UPDATE resultMappings SET setId = NEW.id WHERE setId = OLD.id;
END;
CREATE TRIGGER IF NOT EXISTS authorIdUpdate
AFTER UPDATE OF id
ON authors
FOR EACH ROW
BEGIN
UPDATE resultMappings SET authorId = NEW.id WHERE authorId = OLD.id;
END;
CREATE TRIGGER IF NOT EXISTS rollableResultIdDelete
AFTER DELETE
ON rollableResults
FOR EACH ROW
BEGIN
DELETE FROM resultMappings WHERE resultId = OLD.id;
END;
CREATE TRIGGER IF NOT EXISTS resultSetIdDelete
AFTER DELETE
ON resultSets
FOR EACH ROW
BEGIN
DELETE FROM resultMappings WHERE setId = OLD.id;
END;
CREATE TRIGGER IF NOT EXISTS authorIdDelete
AFTER DELETE
ON authors
FOR EACH ROW
BEGIN
UPDATE resultMappings SET authorId = NULL WHERE authorId = OLD.id;
END;
DROP TRIGGER IF EXISTS rollableTableIdUpdate;
DROP TRIGGER IF EXISTS rollableTableDelete;
DROP TRIGGER IF EXISTS responseInserted;
DROP TRIGGER IF EXISTS responseTableIdUpdated;
ALTER TABLE responses
RENAME TO responsesOriginal;
CREATE TRIGGER IF NOT EXISTS rollableTableIdUpdate
AFTER UPDATE OF id
ON rollableTables
FOR EACH ROW
BEGIN
UPDATE rollableTableIdentifiers SET tableId = NEW.id WHERE tableId = OLD.id;
UPDATE rollableTableHeaders SET tableId = NEW.id WHERE tableId = OLD.id;
UPDATE rollableTableBadges SET tableId = NEW.id WHERE tableId = OLD.id;
UPDATE rollableResults SET tableId = NEW.id WHERE tableId = OLD.id;
END;
CREATE TRIGGER IF NOT EXISTS rollableTableDelete
AFTER DELETE
ON rollableTables
FOR EACH ROW
BEGIN
SELECT RAISE(ABORT, 'rollable table is still referenced')
FROM (SELECT NULL
FROM rollableTableHeaders
WHERE rollableTableHeaders.tableId = OLD.id
UNION ALL
SELECT NULL
FROM rollableTableIdentifiers
WHERE rollableTableIdentifiers.tableId = OLD.id
UNION ALL
SELECT NULL
FROM rollableTableBadges
WHERE rollableTableBadges.tableId = OLD.id);
DELETE FROM rollableResults WHERE tableId = OLD.id;
END;
CREATE VIEW IF NOT EXISTS responses AS
SELECT resultMappings.created AS id,
rollableResults.tableId AS tableId,
rollableResults.text AS text,
resultMappings.updated AS timestamp,
authors.discordSnowflake AS userSnowflake,
(CASE
WHEN resultSets.discordSnowflake = authors.discordSnowflake THEN NULL
ELSE resultSets.discordSnowflake
END) AS serverSnowflake,
(CASE
WHEN resultSets.global = 1 THEN 0
WHEN resultSets.discordSnowflake = authors.discordSnowflake THEN 2
ELSE 1
END) AS access
FROM resultMappings
INNER JOIN rollableResults ON resultMappings.resultId = rollableResults.id
INNER JOIN authors ON resultMappings.authorId = authors.id
INNER JOIN resultSets ON resultMappings.setId = resultSets.id
WHERE resultSets.discordSnowflake IS NOT NULL;
-- crash if we have any differences
CREATE TABLE intentionallyCrash
(
differences TEXT CHECK (differences = 'existing between the view and the original table')
) STRICT;
INSERT INTO intentionallyCrash (differences)
SELECT 'uh oh'
FROM (SELECT *
FROM (SELECT * FROM responsesOriginal EXCEPT SELECT * FROM responses)
UNION ALL
SELECT *
FROM (SELECT * FROM responses EXCEPT SELECT * FROM responsesOriginal));
DROP TABLE intentionallyCrash;
DROP TABLE responsesOriginal;
CREATE TRIGGER IF NOT EXISTS responsesInserted
INSTEAD OF INSERT
ON responses
FOR EACH ROW
BEGIN
INSERT OR IGNORE INTO resultSets (discordSnowflake, global)
VALUES (COALESCE(NEW.serverSnowflake, NEW.userSnowflake),
CASE
WHEN NEW.access = 0 THEN 1
WHEN NEW.access = 1 THEN 0
WHEN NEW.access = 2 THEN 0
ELSE RAISE(ABORT, 'access must be in 0, 1, 2')
END);
INSERT OR IGNORE INTO rollableResults (tableId, text)
VALUES (CASE
WHEN NEW.tableId IN (SELECT id FROM rollableTables) THEN NEW.tableId
ELSE RAISE(ABORT, 'tableId must belong to an existing table')
END, NEW.text);
INSERT OR IGNORE INTO authors (discordSnowflake, authorshipTypeId)
VALUES (NEW.userSnowflake,
(SELECT authorshipTypes.id FROM authorshipTypes WHERE authorshipTypes.name = 'Discord contributor'));
INSERT OR ABORT INTO resultMappings (resultId, setId, authorId, created, updated)
VALUES ((SELECT id FROM rollableResults WHERE tableId = NEW.tableId AND text = NEW.text),
(SELECT id
FROM resultSets
WHERE discordSnowflake = CASE
WHEN NEW.access = 0 THEN ''
WHEN NEW.access = 1 THEN NEW.serverSnowflake
WHEN NEW.access = 2 THEN NEW.userSnowflake
ELSE RAISE(ABORT, 'access must be in 0, 1, 2')
END),
(SELECT id FROM authors WHERE discordSnowflake = NEW.userSnowflake),
NEW.id,
NEW.timestamp);
END;
CREATE TRIGGER IF NOT EXISTS responsesUpdated
INSTEAD OF UPDATE
ON responses
FOR EACH ROW
BEGIN
INSERT OR IGNORE INTO resultSets (discordSnowflake, global)
VALUES (COALESCE(NEW.serverSnowflake, NEW.userSnowflake),
CASE
WHEN NEW.access = 0 THEN 1
WHEN NEW.access = 1 THEN 0
WHEN NEW.access = 2 THEN 0
ELSE RAISE(ABORT, 'access must be in 0, 1, 2')
END);
INSERT OR IGNORE INTO rollableResults (tableId, text)
VALUES (CASE
WHEN NEW.tableId IN (SELECT id FROM rollableTables) THEN NEW.tableId
ELSE RAISE(ABORT, 'tableId must belong to an existing table')
END, NEW.text);
INSERT OR IGNORE INTO authors (discordSnowflake, authorshipTypeId)
VALUES (NEW.userSnowflake,
(SELECT authorshipTypes.id FROM authorshipTypes WHERE authorshipTypes.name = 'Discord contributor'));
UPDATE OR ABORT resultMappings
SET resultId = (SELECT id FROM rollableResults WHERE tableId = NEW.tableId AND text = NEW.text),
setId = (SELECT id
FROM resultSets
WHERE discordSnowflake = COALESCE(NEW.serverSnowflake, NEW.userSnowflake)
AND global = CASE
WHEN NEW.access = 0 THEN 1
WHEN NEW.access = 1 THEN 0
WHEN NEW.access = 2 THEN 0
ELSE RAISE(ABORT, 'access must be in 0, 1, 2')
END),
authorId = (SELECT id FROM authors WHERE discordSnowflake = NEW.userSnowflake),
created = NEW.id,
updated = NEW.timestamp
WHERE resultId = (SELECT id FROM rollableResults WHERE tableId = OLD.tableId AND text = OLD.text)
AND setId = (SELECT id
FROM resultSets
WHERE discordSnowflake = COALESCE(OLD.serverSnowflake, OLD.userSnowflake)
AND global = CASE
WHEN OLD.access = 0 THEN 1
WHEN OLD.access = 1 THEN 0
WHEN OLD.access = 2 THEN 0
END)
AND authorId = (SELECT id FROM authors WHERE discordSnowflake = OLD.userSnowflake);
END;
CREATE TRIGGER IF NOT EXISTS responsesDeleted
INSTEAD OF DELETE
ON responses
FOR EACH ROW
BEGIN
DELETE
FROM resultMappings
WHERE resultId = (SELECT id FROM rollableResults WHERE tableId = OLD.tableId AND text = OLD.text)
AND setId = (SELECT id
FROM resultSets
WHERE discordSnowflake = COALESCE(OLD.serverSnowflake, OLD.userSnowflake)
AND global = CASE
WHEN OLD.access = 0 THEN 1
WHEN OLD.access = 1 THEN 0
WHEN OLD.access = 2 THEN 0
END)
AND authorId = (SELECT id FROM authors WHERE discordSnowflake = OLD.userSnowflake);
END;