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.
 
 

878 lines
35 KiB

import { type QueryDefinitions, validatedDefinitions } from './querytypes.js';
import {
boolean,
discordSnowflake,
jsonArray,
nullable,
string,
substring,
tableIdentifierOrId,
tableIdentifierSubstring,
timestamp,
URL
} from './validators.js';
import { guaranteedSingleton, jsonParser, nothing, rows, singleton, writeCount } from './transformers.js';
export const DatabaseQueries = validatedDefinitions({
autocompleteTable: {
query: `WITH matchingIds (id) AS (SELECT DISTINCT rollableTableIdentifiers.tableId AS id
FROM rollableTableIdentifiers
WHERE rollableTableIdentifiers.identifier LIKE ?1 ESCAPE '\\'
UNION
SELECT DISTINCT rollableTableHeaders.tableId AS id
FROM rollableTableHeaders
WHERE rollableTableHeaders.header LIKE ?1 ESCAPE '\\'
UNION
SELECT DISTINCT rollableTableBadges.id AS id
FROM rollableTableBadges
WHERE rollableTableBadges.badge LIKE ?1 ESCAPE '\\')
SELECT rollableTables.identifier AS identifier,
rollableTables.name AS name,
rollableTables.emoji AS emoji
FROM rollableTables
WHERE ?1 = '%'
OR rollableTables.id IN matchingIds
LIMIT 25;`,
parameters: {
'tableIdentifierSubstring': { validator: tableIdentifierSubstring, index: 1 }
},
output: rows<{ identifier: string, name: string, emoji: string }>()
},
autocompleteTextForDiscordSet: {
query: `WITH matchingTables (id) AS (SELECT DISTINCT rollableTableIdentifiers.tableId AS id
FROM rollableTableIdentifiers
WHERE rollableTableIdentifiers.identifier LIKE ?2 ESCAPE '\\'
UNION
SELECT DISTINCT rollableTableHeaders.tableId AS id
FROM rollableTableHeaders
WHERE rollableTableHeaders.header LIKE ?2 ESCAPE '\\'
UNION
SELECT DISTINCT rollableTableBadges.id AS id
FROM rollableTableBadges
WHERE rollableTableBadges.badge LIKE ?2 ESCAPE '\\'),
rollableSets (id) AS (SELECT resultSets.id
FROM resultSets
WHERE (?4 AND resultSets.global)
OR resultSets.discordSnowflake = ?1)
SELECT rollableResults.text AS text
FROM rollableResults
WHERE rollableResults.tableId IN matchingTables
AND EXISTS(SELECT resultMappings.resultId
FROM resultMappings
WHERE resultMappings.setId IN rollableSets
AND resultMappings.resultId = rollableResults.id)
AND (?3 = '%' OR rollableResults.text LIKE ?3 ESCAPE '\\')
ORDER BY (rollableResults.text LIKE SUBSTR(1, ?3) ESCAPE '\\') DESC,
LENGTH(rollableResults.text)
LIMIT 25;`,
parameters: {
'setSnowflake': { validator: discordSnowflake, index: 1 },
'tableIdentifierSubstring': { validator: tableIdentifierSubstring, index: 2 },
'pattern': { validator: substring, index: 3 },
'includeGlobal': { validator: boolean, index: 4 }
},
output: rows<{ text: string }>()
},
addResultForAddMapping: {
query: `WITH rollableTable (id) AS (SELECT rollableTableIdentifiers.tableId
FROM rollableTableIdentifiers
WHERE (rollableTableIdentifiers.identifier = ?1 OR
rollableTableIdentifiers.tableId = ?1))
INSERT
OR
IGNORE
INTO rollableResults (tableId, text)
VALUES ((SELECT rollableTable.id FROM rollableTable), ?2);`,
parameters: {
'tableIdentifier': {
validator: tableIdentifierOrId,
index: 1
},
'text': {
validator: string,
index: 2
}
},
output: nothing()
},
addDiscordAuthorForAddMapping: {
query: `WITH authorshipType (id) AS (SELECT authorshipTypes.id
FROM authorshipTypes
WHERE authorshipTypes.name = 'Discord contributor')
INSERT
INTO authors (name, url, discordSnowflake, discordUsername, authorshipTypeId)
VALUES (NULL, NULL, ?1, ?2, (SELECT authorshipType.id FROM authorshipType))
ON CONFLICT DO UPDATE SET discordUsername = ?2;`,
parameters: {
'userSnowflake': {
validator: discordSnowflake,
index: 1
},
'username': {
validator: string,
index: 2
}
},
output: nothing()
},
addDiscordSetForAddMapping: {
query: `INSERT OR IGNORE INTO resultSets (name, description, discordSnowflake, creatorId, global)
VALUES (NULL, NULL, ?1, (SELECT authors.id FROM authors WHERE authors.discordSnowflake = ?2), FALSE)`,
parameters: {
'setSnowflake': {
validator: discordSnowflake,
index: 1
},
'userSnowflake': {
validator: discordSnowflake,
index: 2
}
},
output: nothing()
},
addDiscordResultMapping: {
query: `WITH rollableTable (id) AS (SELECT rollableTableIdentifiers.tableId
FROM rollableTableIdentifiers
WHERE rollableTableIdentifiers.identifier = ?2
OR rollableTableIdentifiers.tableId = ?2
LIMIT 1),
rollableResult (id) AS (SELECT rollableResults.id
FROM rollableResults
WHERE rollableResults.text = ?3
AND rollableResults.tableId = (SELECT id FROM rollableTable)
LIMIT 1),
resultSet (id) AS (SELECT resultSets.id
FROM resultSets
WHERE resultSets.discordSnowflake = ?5
AND NOT resultSets.global
LIMIT 1),
author (id) AS (SELECT authors.id
FROM authors
WHERE authors.discordSnowflake = ?4
LIMIT 1)
INSERT
OR
IGNORE
INTO resultMappings (resultId, setId, authorId, created, updated)
VALUES ((SELECT rollableResult.id FROM rollableResult),
(SELECT resultSet.id FROM resultSet),
(SELECT author.id FROM author),
?1,
?1);`,
parameters: {
'timestamp': {
validator: timestamp,
index: 1
},
'tableIdentifier': {
validator: tableIdentifierOrId,
index: 2
},
'resultText': {
validator: string,
index: 3
},
'userSnowflake': {
validator: discordSnowflake,
index: 4
},
'setSnowflake': {
validator: discordSnowflake,
index: 5
}
},
output: nothing()
},
getResultMappingsForDiscordSet: {
query: `WITH rollableTable (id) AS (SELECT rollableTableIdentifiers.tableId
FROM rollableTableIdentifiers
WHERE rollableTableIdentifiers.identifier = ?2
OR rollableTableIdentifiers.tableId = ?2
LIMIT 1),
visibleSets (id) AS (SELECT resultSets.id
FROM resultSets
WHERE ((?5 AND resultSets.global) OR resultSets.discordSnowflake = ?4))
SELECT resultMappings.id AS mappingId,
rollableResults.id AS resultId,
rollableResults.text AS resultText,
authors.id AS authorId,
COALESCE(authors.name, authorshipTypes.defaultAuthor) AS authorName,
authors.url AS authorUrl,
authorshipTypes.relationPrefix AS authorRelation,
resultSets.id AS setId,
resultSets.name AS setName,
resultSets.description AS setDescription,
resultSets.global AS setGlobal,
rollableTables.id AS tableId,
rollableTables.identifier AS tableIdentifier,
rollableTables.name AS tableName,
rollableTables.title AS tableTitle,
rollableTables.emoji AS tableEmoji,
rollableTables.header AS tableHeader,
rollableTables.ordinal AS tableOrdinal,
resultMappings.updated AS updated,
(CASE WHEN resultMappings.updated = ?1 THEN 'updated' ELSE 'existing' END) AS status
FROM resultMappings
INNER JOIN rollableResults ON rollableResults.id = resultMappings.resultId
LEFT JOIN authors ON authors.id = resultMappings.authorId
LEFT JOIN authorshipTypes ON authorshipTypes.id = authors.authorshipTypeId
INNER JOIN resultSets ON resultSets.id = resultMappings.setId
INNER JOIN rollableTables ON rollableTables.id = rollableResults.tableId
WHERE rollableResults.tableId = (SELECT id FROM rollableTable)
AND rollableResults.text = ?3
AND resultMappings.setId IN visibleSets
ORDER BY (NOT setGlobal) DESC, (authorId IS NOT NULL) DESC, updated, mappingId;`,
parameters: {
'timestamp': {
validator: nullable(timestamp),
index: 1
},
'tableIdentifier': {
validator: tableIdentifierOrId,
index: 2
},
'text': {
validator: string,
index: 3
},
'setSnowflake': {
validator: discordSnowflake,
index: 4
},
'includeGlobal': {
validator: boolean,
index: 5
}
},
output: rows<{
mappingId: number,
resultId: number,
resultText: string,
authorId: number | null,
authorName: string | null,
authorUrl: string | null,
authorRelation: string | null,
setId: number,
setName: string | null,
setDescription: string | null,
setGlobal: number,
tableId: number,
tableIdentifier: string,
tableName: string,
tableTitle: string,
tableEmoji: string,
tableHeader: string,
tableOrdinal: number,
updated: number,
status: 'updated' | 'existing'
}>()
},
addResultForEditMapping: {
query: `WITH rollableTable(id) AS (SELECT rollableTableIdentifiers.tableId
FROM rollableTableIdentifiers
WHERE (rollableTableIdentifiers.identifier = ?1 OR
rollableTableIdentifiers.tableId = ?1)
LIMIT 1),
oldResult (id) AS (SELECT rollableResults.id
FROM rollableResults
WHERE rollableResults.tableId = (SELECT rollableTable.id FROM rollableTable)
AND rollableResults.text = ?2
LIMIT 1),
targetSet (id) AS (SELECT resultSets.id FROM resultSets WHERE resultSets.discordSnowflake = ?4 LIMIT 1)
INSERT
OR
IGNORE
INTO rollableResults (tableId, text)
SELECT rollableTable.id, ?3
FROM rollableTable
WHERE ?2 != ?3
AND EXISTS (SELECT resultMappings.id
FROM resultMappings
WHERE resultMappings.resultId = (SELECT oldResult.id FROM oldResult)
AND resultMappings.setId = (SELECT targetSet.id FROM targetSet));`,
parameters: {
'tableIdentifier': {
validator: tableIdentifierOrId,
index: 1
},
'oldText': {
validator: string,
index: 2
},
'newText': {
validator: string,
index: 3
},
'setSnowflake': {
validator: discordSnowflake,
index: 4
}
},
output: nothing()
},
addDiscordAuthorForEditMapping: {
query: `WITH authorshipType (id) AS (SELECT authorshipTypes.id
FROM authorshipTypes
WHERE authorshipTypes.name = 'Discord contributor'
LIMIT 1),
rollableTable (id) AS (SELECT rollableTableIdentifiers.tableId
FROM rollableTableIdentifiers
WHERE rollableTableIdentifiers.identifier = ?3
OR rollableTableIdentifiers.tableId = ?3
LIMIT 1),
oldResult (id) AS (SELECT rollableResults.id
FROM rollableResults
WHERE rollableResults.tableId = (SELECT rollableTable.id FROM rollableTable)
AND rollableResults.text = ?4
LIMIT 1),
newResult (id) AS (SELECT rollableResults.id
FROM rollableResults
WHERE rollableResults.tableId = (SELECT rollableTable.id FROM rollableTable)
AND rollableResults.text = ?5
LIMIT 1),
targetSet (id) AS (SELECT resultSets.id FROM resultSets WHERE resultSets.discordSnowflake = ?6 LIMIT 1)
INSERT
INTO authors (name, url, discordSnowflake, discordUsername, authorshipTypeId)
SELECT NULL AS name,
NULL AS url,
?1 AS discordSnowflake,
?2 AS discordUsername,
authorshipType.id AS authorshipTypeId
FROM authorshipType
WHERE ?4 != ?5
AND EXISTS (SELECT resultMappings.id
FROM resultMappings
WHERE resultMappings.resultId = (SELECT oldResult.id FROM oldResult)
AND resultMappings.setId = (SELECT targetSet.id FROM targetSet))
AND NOT EXISTS (SELECT resultMappings.id
FROM resultMappings
WHERE resultMappings.resultId = (SELECT newResult.id FROM newResult)
AND resultMappings.setId = (SELECT targetSet.id FROM targetSet))
ON CONFLICT DO UPDATE SET discordUsername = ?2;`,
parameters: {
'userSnowflake': {
validator: discordSnowflake,
index: 1
},
'username': {
validator: string,
index: 2
},
'tableIdentifier': {
validator: tableIdentifierOrId,
index: 3
},
'oldText': {
validator: string,
index: 4
},
'newText': {
validator: string,
index: 5
},
'setSnowflake': {
validator: discordSnowflake,
index: 6
}
},
output: nothing()
},
editMappingForDiscord: {
query: `WITH rollableTable (id) AS (SELECT rollableTableIdentifiers.tableId
FROM rollableTableIdentifiers
WHERE rollableTableIdentifiers.identifier = ?2
OR rollableTableIdentifiers.tableId = ?2
LIMIT 1),
oldResult (id) AS (SELECT rollableResults.id
FROM rollableResults
WHERE rollableResults.tableId = (SELECT rollableTable.id FROM rollableTable)
AND rollableResults.text = ?3
LIMIT 1),
newResult(id) AS (SELECT rollableResults.id
FROM rollableResults
WHERE rollableResults.tableId = (SELECT rollableTable.id FROM rollableTable)
AND rollableResults.text = ?4
LIMIT 1),
author(id) AS (SELECT authors.id FROM authors WHERE authors.discordSnowflake = ?5 LIMIT 1),
targetSet(id) AS (SELECT resultSets.id
FROM resultSets
WHERE resultSets.discordSnowflake = ?6
AND NOT resultSets.global
LIMIT 1)
UPDATE OR IGNORE resultMappings
SET resultId = (SELECT id FROM newResult),
authorId = (SELECT id FROM author),
updated = ?1
WHERE ?3 != ?4
AND resultMappings.resultId = (SELECT id FROM oldResult)
AND resultMappings.setId = (SELECT id FROM targetSet);`,
parameters: {
'timestamp': {
validator: timestamp,
index: 1
},
'tableIdentifier': {
validator: tableIdentifierOrId,
index: 2
},
'oldText': {
validator: string,
index: 3
},
'newText': {
validator: string,
index: 4
},
'userSnowflake': {
validator: discordSnowflake,
index: 5
},
'setSnowflake': {
validator: discordSnowflake,
index: 6
}
},
output: nothing()
},
deleteDiscordResultMapping: {
query: `WITH rollableTable (id) AS (SELECT rollableTableIdentifiers.tableId
FROM rollableTableIdentifiers
WHERE rollableTableIdentifiers.identifier = ?1
OR rollableTableIdentifiers.tableId = ?1
LIMIT 1),
oldResult (id) AS (SELECT rollableResults.id
FROM rollableResults
WHERE rollableResults.tableId = (SELECT rollableTable.id FROM rollableTable)
AND rollableResults.text = ?2
LIMIT 1),
targetSet(id) AS (SELECT resultSets.id
FROM resultSets
WHERE resultSets.discordSnowflake = ?3
AND NOT resultSets.global
LIMIT 1)
DELETE
FROM resultMappings
WHERE resultId = (SELECT oldResult.id FROM oldResult)
AND setId = (SELECT targetSet.id FROM targetSet);`,
parameters: {
'tableIdentifier': {
validator: tableIdentifierOrId,
index: 1
},
'text': {
validator: string,
index: 2
},
'setSnowflake': {
validator: discordSnowflake,
index: 3
}
},
output: writeCount()
},
generateFromDiscord: {
query: `WITH originalResults (tableId, header, ordinal, text) AS (SELECT rollableTables.id AS tableId,
rollableTables.header AS header,
rollableTables.ordinal AS ordinal,
NULL AS text
FROM rollableTables
WHERE ?3 IS NULL
UNION ALL
SELECT rollableTableHeaders.tableId AS id,
original.value ->> '$[0]' AS header,
original.key AS ordinal,
original.value ->> '$[1]' AS text
FROM json_each(COALESCE(?3, '[]')) original
LEFT JOIN rollableTableHeaders
ON rollableTableHeaders.header = (original.value ->> '$[0]')
ORDER BY ordinal),
selection (tableId)
AS (SELECT COALESCE(rollableTableIdentifiers.tableId, rollableTableHeaders.tableId) AS tableId
FROM json_each(COALESCE(?4, '[]')) selection
LEFT JOIN rollableTableIdentifiers
ON rollableTableIdentifiers.identifier = selection.value
LEFT JOIN rollableTableHeaders
ON rollableTableHeaders.header = selection.value
WHERE COALESCE(rollableTableIdentifiers.tableId, rollableTableHeaders.tableId) IS NOT NULL),
visibleSets (id, global) AS (SELECT resultSets.id, resultSets.global
FROM resultSets
WHERE (resultSets.global OR resultSets.discordSnowflake = ?2)),
usedResults (id) AS (SELECT DISTINCT resultMappings.resultId
FROM resultMappings
WHERE resultMappings.setId IN (SELECT id FROM visibleSets)),
usedTables (id) AS (SELECT DISTINCT rollableResults.tableId
FROM usedResults
INNER JOIN rollableResults ON rollableResults.id = usedResults.id),
usedMappings (id) AS (SELECT (SELECT resultMappings.id
FROM resultMappings
WHERE resultMappings.resultId = usedResults.id
AND resultMappings.setId IN (SELECT id FROM visibleSets)
ORDER BY (NOT visibleSets.global) DESC,
(resultMappings.authorId IS NOT NULL) DESC,
updated
LIMIT 1)
FROM usedResults),
usedAuthors (id) AS (SELECT DISTINCT resultMappings.authorId
FROM usedMappings
INNER JOIN resultMappings ON resultMappings.id = usedMappings.id),
usedSets (id) AS (SELECT DISTINCT resultMappings.setId
FROM usedMappings
INNER JOIN resultMappings ON resultMappings.id = usedMappings.id),
results (resultId, tableId, header, ordinal, originalText) AS
(SELECT (SELECT rollableResults.id
FROM rollableResults
WHERE rollableResults.tableId = originalResult.tableId
AND rollableResults.id IN usedResults
AND ((?1 AND (originalResult.text IS NULL OR ?4 IS NULL OR
originalResult.tableId IN selection)) OR
rollableResults.text = originalResult.text)
ORDER BY RANDOM()
LIMIT 1) AS resultId,
originalResult.tableId AS tableId,
originalResult.header AS header,
originalResult.ordinal AS ordinal,
originalResult.text AS originalText
FROM originalResults AS originalResult)
SELECT resultMappings.id AS mappingId,
rollableResults.id AS resultId,
COALESCE(rollableResults.text, results.originalText, '') AS resultText,
authors.id AS authorId,
COALESCE(authors.name, authorshipTypes.defaultAuthor) AS authorName,
authors.url AS authorUrl,
authorshipTypes.relationPrefix AS authorRelation,
resultSets.id AS setId,
resultSets.name AS setName,
resultSets.description AS setDescription,
resultSets.global AS setGlobal,
rollableTables.id AS tableId,
rollableTables.identifier AS tableIdentifier,
rollableTables.name AS tableName,
COALESCE(
rollableTables.title,
SUBSTR(results.header, INSTR(results.header, ' ') + 1)) AS tableTitle,
COALESCE(
rollableTables.emoji,
SUBSTR(results.header, 1, INSTR(results.header, ' ') - 1)) AS tableEmoji,
results.header AS tableHeader,
results.ordinal AS tableOrdinal,
resultMappings.updated AS updated,
results.tableId IN selection AS selected
FROM results
LEFT JOIN rollableResults ON rollableResults.id = results.resultId
LEFT JOIN rollableTables ON rollableTables.id = results.tableId
LEFT JOIN resultMappings ON resultMappings.id = (SELECT resultMappings.id
FROM resultMappings
INNER JOIN visibleSets ON visibleSets.id = resultMappings.setId
WHERE resultMappings.resultId = results.resultId
ORDER BY (NOT visibleSets.global) DESC,
(resultMappings.authorId IS NOT NULL) DESC,
updated
LIMIT 1)
LEFT JOIN authors ON authors.id = resultMappings.authorId
LEFT JOIN authorshipTypes ON authorshipTypes.id = authors.authorshipTypeId
LEFT JOIN resultSets ON resultSets.id = resultMappings.setId;`,
parameters: {
'reroll': {
validator: boolean,
index: 1
},
'setSnowflake': {
validator: nullable(discordSnowflake),
index: 2
},
'original': {
validator: nullable(jsonArray),
index: 3
},
'selection': {
validator: nullable(jsonArray),
index: 4
}
},
output: rows<{
mappingId: null,
resultId: null,
resultText: string,
authorId: null,
authorName: null,
authorUrl: null,
authorRelation: null,
setId: null,
setName: null,
setDescription: null,
setGlobal: null,
tableId: null,
tableIdentifier: null,
tableName: null,
tableTitle: string,
tableEmoji: string,
tableHeader: string,
tableOrdinal: number,
updated: null,
selected: false;
} | {
mappingId: null,
resultId: null,
resultText: string,
authorId: null,
authorName: null,
authorUrl: null,
authorRelation: null,
setId: null,
setName: null,
setDescription: null,
setGlobal: null,
tableId: number,
tableIdentifier: string,
tableName: string,
tableTitle: string,
tableEmoji: string,
tableHeader: string,
tableOrdinal: number,
updated: null,
selected: boolean,
} | {
mappingId: number,
resultId: number,
resultText: string,
authorId: number | null,
authorName: string | null,
authorUrl: string | null,
authorRelation: string | null,
setId: number,
setName: string | null,
setDescription: string | null,
setGlobal: number,
tableId: number,
tableIdentifier: string,
tableName: string,
tableTitle: string,
tableEmoji: string,
tableHeader: string,
tableOrdinal: number,
updated: number,
selected: boolean,
}>()
},
getDiscordAuthor: {
query: `
SELECT authors.id AS id,
COALESCE(authors.name, authorshipTypes.defaultAuthor) AS name,
authors.url AS url,
authorshipTypes.relationPrefix AS relation
FROM authors
INNER JOIN main.authorshipTypes authorshipTypes on authorshipTypes.id = authors.authorshipTypeId
WHERE authors.discordSnowflake = ?1;`,
parameters: {
'userSnowflake': {
validator: discordSnowflake,
index: 1
}
},
output: singleton<{ id: number, name: string, url: string, relation: string }>()
},
setDiscordAuthor: {
query: `
INSERT INTO authors (discordSnowflake, discordUsername, name, url, authorshipTypeId)
VALUES (?1, ?2, ?3, ?4,
(SELECT authorshipTypes.id FROM authorshipTypes WHERE authorshipTypes.name = 'Discord contributor'))
ON CONFLICT DO UPDATE SET discordUsername = ?2,
name = ?3,
url = ?4;`,
parameters: {
'userSnowflake': {
validator: discordSnowflake,
index: 1
},
'username': {
validator: string,
index: 2
},
'name': {
validator: nullable(string),
index: 3
},
'url': {
validator: nullable(URL),
index: 4
}
},
output: nothing()
},
getFullDatabaseForDiscordSet: {
query: `WITH originalResults (tableId, header, ordinal, text) AS (SELECT rollableTables.id AS tableId,
rollableTables.header AS header,
rollableTables.ordinal AS ordinal,
NULL AS text
FROM rollableTables
WHERE ?3 IS NULL
UNION ALL
SELECT rollableTableHeaders.tableId AS id,
original.value ->> '$[0]' AS header,
original.key AS ordinal,
original.value ->> '$[1]' AS text
FROM json_each(COALESCE(?3, '[]')) original
LEFT JOIN rollableTableHeaders
ON rollableTableHeaders.header = (original.value ->> '$[0]')
ORDER BY ordinal),
selection (tableId)
AS (SELECT COALESCE(rollableTableIdentifiers.tableId, rollableTableHeaders.tableId) AS tableId
FROM json_each(COALESCE(?4, '[]')) selection
LEFT JOIN rollableTableIdentifiers
ON rollableTableIdentifiers.identifier = selection.value
LEFT JOIN rollableTableHeaders
ON rollableTableHeaders.header = selection.value
WHERE COALESCE(rollableTableIdentifiers.tableId, rollableTableHeaders.tableId) IS NOT NULL),
visibleSets (id, global) AS (SELECT resultSets.id, resultSets.global
FROM resultSets
WHERE (resultSets.global OR resultSets.discordSnowflake = ?2)),
usedResults (id) AS (SELECT DISTINCT resultMappings.resultId
FROM resultMappings
WHERE resultMappings.setId IN (SELECT id FROM visibleSets)),
usedTables (id) AS (SELECT DISTINCT rollableResults.tableId
FROM usedResults
INNER JOIN rollableResults ON rollableResults.id = usedResults.id),
usedMappings (id) AS (SELECT (SELECT resultMappings.id
FROM resultMappings
INNER JOIN visibleSets ON resultMappings.setId = visibleSets.id
WHERE resultMappings.resultId = usedResults.id
ORDER BY (NOT visibleSets.global) DESC,
(resultMappings.authorId IS NOT NULL) DESC,
updated
LIMIT 1)
FROM usedResults),
usedAuthors (id) AS (SELECT DISTINCT resultMappings.authorId
FROM usedMappings
INNER JOIN resultMappings ON resultMappings.id = usedMappings.id),
usedSets (id) AS (SELECT DISTINCT resultMappings.setId
FROM usedMappings
INNER JOIN resultMappings ON resultMappings.id = usedMappings.id),
generationResults (resultObj) AS
(SELECT COALESCE((SELECT json_object(
'type', 'mapping',
'mappingId', resultMappings.id)
FROM rollableResults
INNER JOIN resultMappings
ON resultMappings.resultId = rollableResults.id
INNER JOIN usedMappings ON usedMappings.id = resultMappings.id
WHERE rollableResults.tableId = originalResult.tableId
AND rollableResults.id IN usedResults
AND ((?1 AND (originalResult.text IS NULL OR ?4 IS NULL OR
originalResult.tableId IN selection)) OR
rollableResults.text = originalResult.text)
ORDER BY RANDOM()
LIMIT 1),
CASE
WHEN originalResult.tableId IN usedTables THEN json_object(
'type', 'unknownText',
'tableId', originalResult.tableId,
'text', originalResult.text)
ELSE json_object(
'type', 'unknownTable',
'header', originalResult.header,
'title',
SUBSTR(originalResult.header, INSTR(originalResult.header, ' ') + 1),
'emoji',
SUBSTR(originalResult.header, 1, INSTR(originalResult.header, ' ') - 1),
'ordinal', originalResult.ordinal,
'text', originalResult.text) END)
FROM originalResults AS originalResult
WHERE ?1
OR (?3 IS NOT NULL))
SELECT (SELECT json_group_array(json(tableObj))
FROM (SELECT json_object('id', rollableTables.id,
'identifier', rollableTables.identifier,
'name', rollableTables.name,
'title', rollableTables.title,
'emoji', rollableTables.emoji,
'header', rollableTables.header,
'ordinal', rollableTables.ordinal,
'selected', CASE
WHEN rollableTables.id IN selection THEN json('true')
ELSE json('false') END) AS tableObj
FROM usedTables
INNER JOIN rollableTables ON rollableTables.id = usedTables.id)) AS tables,
(SELECT json_group_array(json(setObj))
FROM (SELECT json_object('id', resultSets.id,
'name', resultSets.name,
'description', resultSets.description,
'global', CASE
WHEN resultSets.global THEN json('true')
ELSE json('false') END) AS setObj
FROM usedSets
INNER JOIN resultSets ON resultSets.id = usedSets.id)) AS sets,
(SELECT json_group_array(json(authorObj))
FROM (SELECT json_object('id', authors.id,
'name', COALESCE(authors.name, authorshipTypes.defaultAuthor),
'url', authors.url,
'relation', authorshipTypes.relationPrefix) AS authorObj
FROM usedAuthors
INNER JOIN authors ON authors.id = usedAuthors.id
INNER JOIN authorshipTypes ON authorshipTypes.id = authors.authorshipTypeId)) AS authors,
(SELECT json_group_array(json(mappingObj))
FROM (SELECT json_object('mappingId', resultMappings.id,
'textId', resultMappings.resultId,
'text', rollableResults.text,
'tableId', rollableResults.tableId,
'setId', resultMappings.setId,
'authorId', resultMappings.authorId,
'updated', resultMappings.updated) AS mappingObj
FROM usedMappings
INNER JOIN resultMappings ON resultMappings.id = usedMappings.id
INNER JOIN rollableResults ON rollableResults.id = resultMappings.resultId)) AS mappings,
CASE
WHEN EXISTS (SELECT resultObj FROM generationResults)
THEN (SELECT json_group_array(json(resultObj)) FROM generationResults)
ELSE json('null') END AS results;`,
parameters: {
'reroll': {
validator: boolean,
index: 1
},
'setSnowflake': {
validator: nullable(discordSnowflake),
index: 2
},
'original': {
validator: nullable(jsonArray),
index: 3
},
'selection': {
validator: nullable(jsonArray),
index: 4
}
},
output: guaranteedSingleton(jsonParser<{
tables: {
id: number,
identifier: string,
name: string,
title: string,
emoji: string,
header: string,
ordinal: number,
selected: boolean
}[]
sets: { id: number, name: string | null, description: string | null, global: boolean }[],
authors: { id: number, name: string, url: string | null, relation: string }[],
mappings: {
mappingId: number,
textId: number,
text: string,
tableId: number,
setId: number,
authorId: number,
updated: number
}[],
results: (({ type: 'mapping', mappingId: number } | { type: 'unknownText', tableId: number, text: string } | {
type: 'unknownTable',
header: string,
title: string,
emoji: string,
ordinal: number,
text: string
})[]) | null
}>(['tables', 'sets', 'authors', 'mappings', 'results']))
}
} as const satisfies QueryDefinitions);