parent
931dc488cd
commit
33b084b575
@ -0,0 +1,134 @@ |
||||
/* |
||||
* Graphile Migrate configuration. |
||||
* |
||||
* If you decide to commit this file (recommended) please ensure that it does |
||||
* not contain any secrets (passwords, etc) - we recommend you manage these |
||||
* with environmental variables instead. |
||||
* |
||||
* This file is in JSON5 format, in VSCode you can use "JSON with comments" as |
||||
* the file format. |
||||
*/ |
||||
{ |
||||
/* |
||||
* connectionString: this tells Graphile Migrate where to find the database |
||||
* to run the migrations against. |
||||
* |
||||
* RECOMMENDATION: use `DATABASE_URL` envvar instead. |
||||
*/ |
||||
// "connectionString": "postgres://appuser:apppassword@host:5432/appdb", |
||||
|
||||
/* |
||||
* shadowConnectionString: like connectionString, but this is used for the |
||||
* shadow database (which will be reset frequently). |
||||
* |
||||
* RECOMMENDATION: use `SHADOW_DATABASE_URL` envvar instead. |
||||
*/ |
||||
// "shadowConnectionString": "postgres://appuser:apppassword@host:5432/appdb_shadow", |
||||
|
||||
/* |
||||
* rootConnectionString: like connectionString, but this is used for |
||||
* dropping/creating the database in `graphile-migrate reset`. This isn't |
||||
* necessary, shouldn't be used in production, but helps during development. |
||||
* |
||||
* RECOMMENDATION: use `ROOT_DATABASE_URL` envvar instead. |
||||
*/ |
||||
// "rootConnectionString": "postgres://adminuser:adminpassword@host:5432/postgres", |
||||
|
||||
/* |
||||
* pgSettings: key-value settings to be automatically loaded into PostgreSQL |
||||
* before running migrations, using an equivalent of `SET LOCAL <key> TO |
||||
* <value>` |
||||
*/ |
||||
"pgSettings": { |
||||
// "search_path": "app_public,app_private,app_hidden,public", |
||||
}, |
||||
/* |
||||
* placeholders: substituted in SQL files when compiled/executed. Placeholder |
||||
* keys should be prefixed with a colon and in all caps, like |
||||
* `:COLON_PREFIXED_ALL_CAPS`. Placeholder values should be strings. They |
||||
* will be replaced verbatim with NO ESCAPING AT ALL (this differs from how |
||||
* psql handles placeholders) so should only be used with "safe" values. This |
||||
* is useful for committing migrations where certain parameters can change |
||||
* between environments (development, staging, production) but you wish to |
||||
* use the same signed migration files for all. |
||||
* |
||||
* The special value "!ENV" can be used to indicate an environmental variable |
||||
* of the same name should be used. |
||||
* |
||||
* Graphile Migrate automatically sets the `:DATABASE_NAME` and |
||||
* `:DATABASE_OWNER` placeholders, and you should not attempt to override |
||||
* these. |
||||
*/ |
||||
"placeholders": { |
||||
// ":DATABASE_VISITOR": "!ENV", // Uses process.env.DATABASE_VISITOR |
||||
}, |
||||
/* |
||||
* Actions allow you to run scripts or commands at certain points in the |
||||
* migration lifecycle. SQL files are ran against the database directly. |
||||
* "command" actions are ran with the following environmental variables set: |
||||
* |
||||
* - GM_DBURL: the PostgreSQL URL of the database being migrated |
||||
* - GM_DBNAME: the name of the database from GM_DBURL |
||||
* - GM_DBUSER: the user from GM_DBURL |
||||
* - GM_SHADOW: set to 1 if the shadow database is being migrated, left unset |
||||
* otherwise |
||||
* |
||||
* If "shadow" is unspecified, the actions will run on events to both shadow |
||||
* and normal databases. If "shadow" is true the action will only run on |
||||
* actions to the shadow DB, and if false only on actions to the main DB. |
||||
*/ |
||||
|
||||
/* |
||||
* afterReset: actions executed after a `graphile-migrate reset` command. |
||||
*/ |
||||
"afterReset": [ |
||||
// "afterReset.sql", |
||||
// { "_": "command", "command": "graphile-worker --schema-only" }, |
||||
], |
||||
/* |
||||
* afterAllMigrations: actions executed once all migrations are complete. |
||||
*/ |
||||
"afterAllMigrations": [ |
||||
// { |
||||
// "_": "command", |
||||
// "shadow": true, |
||||
// "command": "if [ \"$IN_TESTS\" != \"1\" ]; then ./scripts/dump-db; fi", |
||||
// }, |
||||
], |
||||
/* |
||||
* afterCurrent: actions executed once the current migration has been |
||||
* evaluated (i.e. in watch mode). |
||||
*/ |
||||
"afterCurrent": [ |
||||
// { |
||||
// "_": "command", |
||||
// "shadow": true, |
||||
// "command": "if [ \"$IN_TESTS\" = \"1\" ]; then ./scripts/test-seed; fi", |
||||
// }, |
||||
], |
||||
/* |
||||
* blankMigrationContent: content to be written to the current migration |
||||
* after commit. NOTE: this should only contain comments. |
||||
*/ |
||||
// "blankMigrationContent": "-- Write your migration here\n", |
||||
|
||||
/****************************************************************************\ |
||||
*** *** |
||||
*** You probably don't want to edit anything below here. *** |
||||
*** *** |
||||
\****************************************************************************/ |
||||
|
||||
/* |
||||
* manageGraphileMigrateSchema: if you set this false, you must be sure to |
||||
* keep the graphile_migrate schema up to date yourself. We recommend you |
||||
* leave it at its default. |
||||
*/ |
||||
// "manageGraphileMigrateSchema": true, |
||||
|
||||
/* |
||||
* migrationsFolder: path to the folder in which to store your migrations. |
||||
*/ |
||||
// migrationsFolder: "./migrations", |
||||
|
||||
"//generatedWith": "1.2.0" |
||||
} |
@ -0,0 +1,14 @@ |
||||
<?xml version="1.0" encoding="UTF-8"?> |
||||
<project version="4"> |
||||
<component name="DataSourceManagerImpl" format="xml" multifile-model="true"> |
||||
<data-source source="LOCAL" name="Local Development Database" read-only="true" uuid="f45c1a42-afba-45e3-a87c-3a0e1ff84111"> |
||||
<driver-ref>postgresql</driver-ref> |
||||
<synchronize>true</synchronize> |
||||
<schema-control>AUTOMATIC</schema-control> |
||||
<rewrite-bounds>false</rewrite-bounds> |
||||
<jdbc-driver>org.postgresql.Driver</jdbc-driver> |
||||
<jdbc-url>jdbc:postgresql://localhost:5432/gacha-prod</jdbc-url> |
||||
<working-dir>$ProjectFileDir$</working-dir> |
||||
</data-source> |
||||
</component> |
||||
</project> |
@ -0,0 +1,6 @@ |
||||
<?xml version="1.0" encoding="UTF-8"?> |
||||
<project version="4"> |
||||
<component name="SqlDialectMappings"> |
||||
<file url="PROJECT" dialect="PostgreSQL" /> |
||||
</component> |
||||
</project> |
@ -1,45 +1,4 @@ |
||||
<?xml version="1.0" encoding="UTF-8"?> |
||||
<project version="4"> |
||||
<component name="ProjectTasksOptions" suppressed-tasks="Pug/Jade"> |
||||
<TaskOptions isEnabled="true"> |
||||
<option name="arguments" value="format" /> |
||||
<option name="checkSyntaxErrors" value="true" /> |
||||
<option name="description" /> |
||||
<option name="exitCodeBehavior" value="ERROR" /> |
||||
<option name="fileExtension" value="prisma" /> |
||||
<option name="immediateSync" value="true" /> |
||||
<option name="name" value="Schema reformat" /> |
||||
<option name="output" value="$PROJECT_DIR$/prisma/schema.prisma" /> |
||||
<option name="outputFilters"> |
||||
<array /> |
||||
</option> |
||||
<option name="outputFromStdout" value="false" /> |
||||
<option name="program" value="$PROJECT_DIR$/node_modules/.bin/prisma" /> |
||||
<option name="runOnExternalChanges" value="false" /> |
||||
<option name="scopeName" value="Project Files" /> |
||||
<option name="trackOnlyRoot" value="false" /> |
||||
<option name="workingDir" value="$PROJECT_DIR$" /> |
||||
<envs /> |
||||
</TaskOptions> |
||||
<TaskOptions isEnabled="true"> |
||||
<option name="arguments" value="generate" /> |
||||
<option name="checkSyntaxErrors" value="true" /> |
||||
<option name="description" /> |
||||
<option name="exitCodeBehavior" value="ERROR" /> |
||||
<option name="fileExtension" value="prisma" /> |
||||
<option name="immediateSync" value="true" /> |
||||
<option name="name" value="Schema Regeneration" /> |
||||
<option name="output" value="$PROJECT_DIR$/node_modules/@prisma/client" /> |
||||
<option name="outputFilters"> |
||||
<array /> |
||||
</option> |
||||
<option name="outputFromStdout" value="false" /> |
||||
<option name="program" value="$PROJECT_DIR$/node_modules/.bin/prisma" /> |
||||
<option name="runOnExternalChanges" value="true" /> |
||||
<option name="scopeName" value="prisma" /> |
||||
<option name="trackOnlyRoot" value="false" /> |
||||
<option name="workingDir" value="$PROJECT_DIR$" /> |
||||
<envs /> |
||||
</TaskOptions> |
||||
</component> |
||||
<component name="ProjectTasksOptions" suppressed-tasks="Pug/Jade" /> |
||||
</project> |
@ -0,0 +1,32 @@ |
||||
--! Previous: - |
||||
--! Hash: sha1:183d67042c756db13c07c3f3c6b8bd5301d47239 |
||||
--! Message: DiscordChannel table |
||||
|
||||
--- Table used to manage Discord channels known to the server and permissions thereon. |
||||
CREATE TABLE IF NOT EXISTS DiscordChannel |
||||
( |
||||
--- The ID of the channel in Discord, as a decimal string. |
||||
discordId VARCHAR(20) PRIMARY KEY NOT NULL, |
||||
--- The last known name of this channel. |
||||
name VARCHAR(100) NOT NULL, |
||||
--- True if this channel should be used to broadcast public game events. |
||||
broadcastGame BOOLEAN NOT NULL DEFAULT FALSE, |
||||
--- True if this channel should be used to send logs. |
||||
sendLogs BOOLEAN NOT NULL DEFAULT FALSE, |
||||
--- True if this channel can accept game commands. |
||||
acceptGameCommands BOOLEAN NOT NULL DEFAULT FALSE, |
||||
--- True if this channel can accept admin commands. |
||||
acceptAdminCommands BOOLEAN NOT NULL DEFAULT FALSE, |
||||
--- The priority of this channel when slowing down to account for rate limits. Higher is more important. |
||||
priority SMALLINT NOT NULL DEFAULT 0, |
||||
--- The snowflake ID of the guild in which this channel exists, if it's known. |
||||
guildId VARCHAR(20) DEFAULT NULL, |
||||
--- The snowflake ID of the webhook used to post to this channel. Nulled out if the webhook 404s. |
||||
webhookId VARCHAR(20) DEFAULT NULL, |
||||
--- The webhook token used to post to this channel. Nulled out if the webhook 404s. |
||||
webhookToken VARCHAR(20) DEFAULT NULL, |
||||
--- Verifies that the webhook ID and token are always set or unset together. |
||||
CONSTRAINT DiscordChannel_WebhookPair CHECK ( |
||||
(webhookId IS NULL AND webhookToken IS NULL) |
||||
OR (webhookId IS NOT NULL AND webhookToken IS NOT NULL)) |
||||
); |
@ -0,0 +1,21 @@ |
||||
--! Previous: sha1:183d67042c756db13c07c3f3c6b8bd5301d47239 |
||||
--! Hash: sha1:848f1f09a7cd93047aa139d0c4fc203f9ab6ccc4 |
||||
--! Message: Gender table and initial values |
||||
|
||||
--- Table of user genders. |
||||
CREATE TABLE IF NOT EXISTS Gender |
||||
( |
||||
--- The internal ID, usually a few lower-case characters roughly representing this gender. |
||||
id VARCHAR(8) PRIMARY KEY NOT NULL, |
||||
--- The name of this gender for use in tables et al. This should be the name of the gender |
||||
--- (e.g., "Female", "Male", "Nonbinary") not the name for a person of that gender. |
||||
name VARCHAR(100) UNIQUE NOT NULL |
||||
); |
||||
|
||||
--- Default genders. |
||||
INSERT INTO Gender |
||||
(id, name) |
||||
VALUES ('f', 'Female'), |
||||
('nb', 'Non-binary'), |
||||
('m', 'Male') |
||||
ON CONFLICT DO NOTHING; |
@ -0,0 +1,31 @@ |
||||
--! Previous: sha1:848f1f09a7cd93047aa139d0c4fc203f9ab6ccc4 |
||||
--! Hash: sha1:d16f7d7c74ee0a1f58ac87a09de124d165088661 |
||||
--! Message: Player table |
||||
|
||||
--- Table of in-game user data structures. |
||||
CREATE TABLE IF NOT EXISTS Player |
||||
( |
||||
--- The internal ID associated with this account. |
||||
--- It's separate from the Discord ID associated with this account. This supports a few things: |
||||
--- 1) We can move the game off of Discord, or add the ability to play it as a separate phone app or webapp, |
||||
--- without losing our database. |
||||
--- 2) If necessary, we can support having multiple Discord users associated with the same user account, to |
||||
--- support multi-account play. |
||||
--- 3) If necessary, we can support changing the Discord user associated with a user account, if for any reason |
||||
--- they are no longer using the old account and want to switch to a new account. |
||||
id SERIAL PRIMARY KEY NOT NULL, |
||||
--- The user's name, for the purposes of the game. This is completely separate from both their username and nickname |
||||
--- as Discord sees it, though it defaults to their nickname at time of joining. It does not have to be unique, and |
||||
--- can be changed at any time. |
||||
name VARCHAR(100) NOT NULL, |
||||
--- The user's gender, for the purposes of the game. This is purely cosmetic and can be changed at any time. |
||||
genderId VARCHAR(8) NOT NULL REFERENCES Gender (id) ON DELETE RESTRICT ON UPDATE CASCADE, |
||||
--- The number of units of currency this user is currently carrying. |
||||
currency INT NOT NULL, |
||||
--- The time and date at which this user joined. |
||||
joinedAt TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), |
||||
--- The last time this user used a command. |
||||
lastActive TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), |
||||
--- The last time this user retrieved their daily resources. |
||||
lastDaily TIMESTAMP WITH TIME ZONE DEFAULT NULL |
||||
) |
@ -0,0 +1,16 @@ |
||||
--! Previous: sha1:d16f7d7c74ee0a1f58ac87a09de124d165088661 |
||||
--! Hash: sha1:b34f19ae3e3ef87d0d7539803df087e886e1db1c |
||||
--! Message: DiscordUser table |
||||
|
||||
--- Table of information known about Discord users. |
||||
CREATE TABLE IF NOT EXISTS DiscordUser |
||||
( |
||||
--- The Discord ID this record is for. A Discord snowflake. |
||||
discordId VARCHAR(20) PRIMARY KEY NOT NULL, |
||||
--- The last known username associated with this user. |
||||
username VARCHAR(32) NOT NULL, |
||||
--- The last known discriminator associated with this user. |
||||
discriminator VARCHAR(4) NOT NULL, |
||||
--- The Player that this DiscordUser is associated with. |
||||
playerId INT REFERENCES Player (id) ON DELETE SET NULL ON UPDATE CASCADE |
||||
) |
@ -0,0 +1,16 @@ |
||||
--! Previous: sha1:b34f19ae3e3ef87d0d7539803df087e886e1db1c |
||||
--! Hash: sha1:8243b031500fde9c022d6aada10a429496dc264d |
||||
--! Message: UnitTier table |
||||
|
||||
--- Table of definitions of unit tiers. |
||||
CREATE TABLE IF NOT EXISTS UnitTier |
||||
( |
||||
--- The internal ID associated with this tier, a few short characters. |
||||
id VARCHAR(8) NOT NULL PRIMARY KEY, |
||||
--- The human-readable name of this tier. Unique among tiers. |
||||
name VARCHAR(100) NOT NULL UNIQUE, |
||||
--- The chance of pulling a unit of this tier. |
||||
pullWeight INT NOT NULL, |
||||
--- The cost of /recalling a unit of this tier. |
||||
recallCost INT NOT NULL |
||||
) |
@ -0,0 +1,24 @@ |
||||
--! Previous: sha1:8243b031500fde9c022d6aada10a429496dc264d |
||||
--! Hash: sha1:8102b0362d2ae5b73ed1d56214f7fffa445c469e |
||||
--! Message: Unit table |
||||
|
||||
--- Table of definitions of units that can be summoned. |
||||
CREATE TABLE IF NOT EXISTS Unit |
||||
( |
||||
--- The internal ID associated with this unit. |
||||
id SERIAL NOT NULL PRIMARY KEY, |
||||
--- The name of this unit. |
||||
name VARCHAR(50) NOT NULL, |
||||
--- The subtitle of this unit. |
||||
subtitle VARCHAR(50) NOT NULL, |
||||
--- The description of this unit. |
||||
description TEXT NOT NULL, |
||||
--- The tier of this unit. |
||||
tierId VARCHAR(8) NOT NULL REFERENCES UnitTier (id) ON DELETE RESTRICT ON UPDATE CASCADE, |
||||
--- The unit's base health when summoned for the first time. |
||||
baseHealth INT NOT NULL CHECK ( baseHealth > 0 ), |
||||
--- The unit's base strength when summoned for the first time. |
||||
baseStrength INT NOT NULL CHECK ( baseStrength > 0 ), |
||||
--- The combination of Name and Subtitle is unique among units, allowing for multiple versions of a unit. |
||||
UNIQUE (name, subtitle) |
||||
) |
@ -0,0 +1,59 @@ |
||||
--! Previous: sha1:8102b0362d2ae5b73ed1d56214f7fffa445c469e |
||||
--! Hash: sha1:8a890a4c8807eb5a7aae90456ba1e7712cda502b |
||||
--! Message: SummonedUnit table |
||||
|
||||
--- Connection between Players and Units, indicating how and when players have summoned this unit. |
||||
CREATE TABLE IF NOT EXISTS SummonedUnit |
||||
( |
||||
--- The ID of this summoning instance. |
||||
instanceId SERIAL PRIMARY KEY NOT NULL, |
||||
--- The Player that summoned this unit at some point. |
||||
playerId INT NOT NULL REFERENCES Player (id) ON DELETE CASCADE ON UPDATE CASCADE, |
||||
--- The Unit that was summoned by this Player at some point. |
||||
unitId INT NOT NULL REFERENCES Unit (id) ON DELETE CASCADE ON UPDATE CASCADE, |
||||
--- The time and date this instance was summoned by pulling or recalling. |
||||
summonedAt TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), |
||||
--- True if this instance was summoned by /pull (as opposed to /recall). |
||||
wasPulled BOOLEAN NOT NULL DEFAULT FALSE, |
||||
--- True if this instance was summoned by /recall (as opposed to /pull). |
||||
wasRecalled BOOLEAN NOT NULL DEFAULT FALSE, |
||||
--- The timestamps when this unit was resummoned because it appeared in a /pull while already summoned. |
||||
--- Does not include the initial summoning if that summoning happened via /pull. |
||||
resummonings TIMESTAMP WITH TIME ZONE ARRAY DEFAULT NULL, |
||||
--- The time and date this instance was desummoned by digesting or releasing. |
||||
desummonedAt TIMESTAMP WITH TIME ZONE DEFAULT NULL, |
||||
--- The summoned unit (friendly or enemy) that digested this unit, if a summoned unit was responsible and that |
||||
--- summoned unit has not been deleted somehow. |
||||
digestedByInstanceId INT DEFAULT NULL REFERENCES SummonedUnit (instanceId) ON DELETE SET NULL ON UPDATE CASCADE, |
||||
--- True if this instance was desummoned by being digested rather than being released. |
||||
wasDigested BOOLEAN DEFAULT NULL, |
||||
--- True if this instance was desummoned by being released rather than being digested. |
||||
wasReleased BOOLEAN DEFAULT NULL, |
||||
--- The unit's current health. If 0, the unit is unconscious and cannot participate in fights. |
||||
--- At -MaxHealth, the unit has been fully digested and this record will be deleted. |
||||
currentHealth INT NOT NULL, |
||||
--- The unit's maximum health. |
||||
maxHealth INT NOT NULL CHECK (maxHealth > 0), |
||||
--- The unit's strength. |
||||
strength INT NOT NULL CHECK (strength > 0), |
||||
--- The unit's current health must be between maxHealth and -maxHealth (the latter of which means digestion). |
||||
CONSTRAINT SummonedUnit_CurrentHealthBounds CHECK ( |
||||
currentHealth BETWEEN -maxHealth AND maxHealth), |
||||
--- Exactly one of wasPulled or wasRecalled must be TRUE. |
||||
CONSTRAINT SummonedUnit_ExactlyOneOrigin CHECK ( |
||||
((wasPulled IS TRUE OR wasRecalled IS TRUE) AND NOT (wasPulled IS FALSE AND wasRecalled IS FALSE))), |
||||
--- Exactly one of wasDigested or wasReleased must be TRUE if desummonedAt is set, |
||||
--- and both must be NULL if desummonedAt is NULL. |
||||
CONSTRAINT SummonedUnit_ExactlyOneFate CHECK ( |
||||
((wasDigested IS TRUE OR wasReleased IS TRUE) = (desummonedAt IS NOT NULL)) |
||||
AND (wasDigested IS NULL OR wasReleased IS NULL) = (desummonedAt IS NULL)), |
||||
--- The digesting summoned unit's instance ID must be set only if wasDigested is TRUE. |
||||
CONSTRAINT SummonedUnit_DigesterForDigestedOnly CHECK ( |
||||
digestedByInstanceId IS NULL OR wasDigested IS TRUE) |
||||
); |
||||
|
||||
--- No more than one instance of a particular unit may be summoned by the same player. |
||||
--- Once the previous instance has been desummoned (by any method), the unit may be summoned again. |
||||
CREATE UNIQUE INDEX IF NOT EXISTS SummonedUnit_OneInstancePerUnitPerPlayer |
||||
ON SummonedUnit (playerId, unitId) |
||||
WHERE (desummonedAt IS NULL); |
@ -0,0 +1,367 @@ |
||||
--! Previous: sha1:8a890a4c8807eb5a7aae90456ba1e7712cda502b |
||||
--! Hash: sha1:d45df95e7f3a77f0a9f7a8bfc6a93cfbebc1c61e |
||||
--! Message: all the procedures |
||||
|
||||
-- Create indices needed for ChannelManager commands. |
||||
CREATE INDEX IF NOT EXISTS DiscordChannel_GuildId ON DiscordChannel (guildId) WHERE guildId IS NOT NULL; |
||||
CREATE INDEX IF NOT EXISTS DiscordChannel_AcceptsGameCommands ON DiscordChannel (acceptGameCommands) WHERE acceptGameCommands IS TRUE; |
||||
CREATE INDEX IF NOT EXISTS DiscordChannel_AcceptsAdminCommands ON DiscordChannel (acceptAdminCommands) WHERE acceptAdminCommands IS TRUE; |
||||
|
||||
ALTER TABLE DiscordUser |
||||
ADD COLUMN IF NOT EXISTS lastActive TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(); |
||||
|
||||
--- Gets guild IDs where game commands can be used and thus guild commands must be pushed |
||||
CREATE OR REPLACE FUNCTION GetGuildIDsAbleToUseGameCommands() |
||||
RETURNS SETOF DiscordChannel.GuildId%TYPE |
||||
STABLE |
||||
ROWS 1 |
||||
AS |
||||
$$ |
||||
SELECT DISTINCT guildId |
||||
FROM DiscordChannel |
||||
WHERE guildId IS NOT NULL |
||||
AND acceptGameCommands IS TRUE; |
||||
$$ |
||||
LANGUAGE 'sql'; |
||||
|
||||
--- Gets whether the users may use game commands in the current channel/guild. |
||||
--- Error codes: |
||||
--- VGBCG: Bad channel (game). This is not a valid channel to send game commands in. |
||||
--- VGBGG: Bad guild (game). This is not a valid guild to send game commands in. |
||||
CREATE OR REPLACE PROCEDURE CheckGameCommandIn( |
||||
IN requestedChannel DiscordChannel.DiscordId%TYPE, |
||||
IN requestedGuild DiscordChannel.GuildId%TYPE) |
||||
AS |
||||
$$ |
||||
DECLARE |
||||
channelAcceptsGameCommands BOOLEAN; |
||||
channelAcceptsAdminCommands BOOLEAN; |
||||
channelSendsMessages BOOLEAN; |
||||
channelIsKnown BOOLEAN; |
||||
guildSupportsGameCommands BOOLEAN; |
||||
guildSupportsAdminCommands BOOLEAN; |
||||
guildSupportsMessages BOOLEAN; |
||||
guildIsKnown BOOLEAN; |
||||
recommendedChannelId DiscordChannel.DiscordId%TYPE; |
||||
BEGIN |
||||
SELECT acceptGameCommands, acceptAdminCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO channelAcceptsGameCommands, channelAcceptsAdminCommands, channelSendsMessages, channelIsKnown |
||||
FROM DiscordChannel |
||||
WHERE discordId = requestedChannel |
||||
LIMIT 1; |
||||
IF channelAcceptsGameCommands IS NOT TRUE THEN |
||||
SELECT discordId, acceptGameCommands, acceptAdminCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO recommendedChannelId, guildSupportsGameCommands, guildSupportsAdminCommands, guildSupportsMessages, guildIsKnown |
||||
FROM DiscordChannel |
||||
WHERE guildId = requestedGuild |
||||
ORDER BY CASE TRUE |
||||
WHEN acceptGameCommands THEN 3 |
||||
WHEN acceptAdminCommands THEN 2 |
||||
WHEN broadcastGame OR sendLogs THEN 1 |
||||
ELSE 0 |
||||
END DESC, priority DESC |
||||
LIMIT 1; |
||||
IF guildSupportsGameCommands IS TRUE THEN |
||||
RAISE EXCEPTION 'Can''t use game commands in this channel' USING |
||||
ERRCODE = 'VGBCG', |
||||
DETAIL = CASE TRUE |
||||
WHEN channelAcceptsGameCommands THEN format( |
||||
'This channel (<#%>) can only be used to send admin commands, not game commands.', |
||||
requestedChannel) |
||||
WHEN channelSendsMessages THEN format( |
||||
'This channel (<#%>) is only used to receive broadcasts, not send commands.', |
||||
requestedChannel) |
||||
WHEN channelIsKnown THEN format( |
||||
'This channel (<#%>) is unused.', requestedChannel) |
||||
ELSE format('This channel (<#%>) is not known to the system.', requestedChannel) |
||||
END, |
||||
HINT = format( |
||||
'Try sending messages to the channel <#%> in this guild, which does allow game commands.', |
||||
recommendedChannelId); |
||||
ELSE |
||||
RAISE EXCEPTION 'Can''t use game commands in this guild' USING |
||||
ERRCODE = 'VGBGG', |
||||
DETAIL = CASE TRUE |
||||
WHEN guildSupportsAdminCommands THEN |
||||
format('This guild (ID %) only has channels used to send admin commands, ' || |
||||
'not game commands.', requestedGuild) |
||||
WHEN guildSupportsMessages THEN |
||||
format('This guild (ID %) only has channels used to receive broadcasts, ' || |
||||
'not send commands.', requestedGuild) |
||||
WHEN guildIsKnown THEN |
||||
format('This guild (ID %) only has unused channels.', requestedGuild) |
||||
ELSE format('This guild (ID %) is not known to the system.', requestedGuild) |
||||
END, |
||||
HINT = 'As game commands are normally only visible when a guild allows them, ' || |
||||
'this guild may have been removed from the system incorrectly. ' || |
||||
'Ask an admin to check what''s going on.'; |
||||
END IF; |
||||
END IF; |
||||
END; |
||||
$$ LANGUAGE 'plpgsql'; |
||||
|
||||
--- Gets guild IDs where admin commands can be used and thus guild commands must be pushed |
||||
CREATE OR REPLACE FUNCTION GetGuildIDsAbleToUseAdminCommands() |
||||
RETURNS SETOF DiscordChannel.GuildId%TYPE |
||||
STABLE |
||||
ROWS 1 |
||||
AS |
||||
$$ |
||||
SELECT DISTINCT guildId |
||||
FROM DiscordChannel |
||||
WHERE guildId IS NOT NULL |
||||
AND acceptAdminCommands IS TRUE; |
||||
$$ |
||||
LANGUAGE 'sql'; |
||||
|
||||
--- Gets whether the users may use admin commands in the current channel/guild. |
||||
--- Error codes: |
||||
--- VGBCA: Bad channel (admin). This is not a valid channel to send admin commands in. |
||||
--- VGBGA: Bad guild (admin). This is not a valid guild to send admin commands in. |
||||
CREATE OR REPLACE PROCEDURE CheckAdminCommandIn( |
||||
IN requestedChannel DiscordChannel.DiscordId%TYPE, |
||||
IN requestedGuild DiscordChannel.GuildId%TYPE) |
||||
AS |
||||
$$ |
||||
DECLARE |
||||
channelAcceptsAdminCommands BOOLEAN; |
||||
channelAcceptsGameCommands BOOLEAN; |
||||
channelSendsMessages BOOLEAN; |
||||
channelIsKnown BOOLEAN; |
||||
guildSupportsAdminCommands BOOLEAN; |
||||
guildSupportsGameCommands BOOLEAN; |
||||
guildSupportsMessages BOOLEAN; |
||||
guildIsKnown BOOLEAN; |
||||
recommendedChannelId DiscordChannel.DiscordId%TYPE; |
||||
BEGIN |
||||
SELECT acceptAdminCommands, acceptGameCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO channelAcceptsAdminCommands, channelAcceptsGameCommands, channelSendsMessages, channelIsKnown |
||||
FROM DiscordChannel |
||||
WHERE discordId = requestedChannel |
||||
LIMIT 1; |
||||
IF channelAcceptsAdminCommands IS NOT TRUE THEN |
||||
SELECT discordId, acceptAdminCommands, acceptGameCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO recommendedChannelId, guildSupportsAdminCommands, guildSupportsGameCommands, guildSupportsMessages, guildIsKnown |
||||
FROM DiscordChannel |
||||
WHERE guildId = requestedGuild |
||||
ORDER BY CASE TRUE |
||||
WHEN acceptAdminCommands THEN 3 |
||||
WHEN acceptGameCommands THEN 2 |
||||
WHEN broadcastGame OR sendLogs THEN 1 |
||||
ELSE 0 |
||||
END DESC, priority DESC |
||||
LIMIT 1; |
||||
IF guildSupportsAdminCommands IS TRUE THEN |
||||
RAISE EXCEPTION 'Can''t use admin commands in this channel' USING |
||||
ERRCODE = 'VGBCA', |
||||
DETAIL = CASE TRUE |
||||
WHEN channelAcceptsGameCommands THEN format( |
||||
'This channel (<#%>) can only be used to send admin commands, not game commands.', |
||||
requestedChannel) |
||||
WHEN channelSendsMessages THEN format( |
||||
'This channel (<#%>) is only used to receive broadcasts, not send commands.', |
||||
requestedChannel) |
||||
WHEN channelIsKnown THEN format( |
||||
'This channel (<#%>) is unused.', requestedChannel) |
||||
ELSE format('This channel (<#%>) is not known to the system.', requestedChannel) |
||||
END, |
||||
HINT = format( |
||||
'Try sending messages to the channel <#%> in this guild, which does allow game commands.', |
||||
recommendedChannelId); |
||||
ELSE |
||||
RAISE EXCEPTION 'Can''t use admin commands in this guild' USING |
||||
ERRCODE = 'VGBGA', |
||||
DETAIL = CASE TRUE |
||||
WHEN guildSupportsGameCommands THEN |
||||
format('This guild (ID %) only has channels used to send game commands, ' || |
||||
'not admin commands.', requestedGuild) |
||||
WHEN guildSupportsMessages THEN |
||||
format('This guild (ID %) only has channels used to receive broadcasts, ' || |
||||
'not send commands.', requestedGuild) |
||||
WHEN guildIsKnown THEN |
||||
format('This guild (ID %) only has unused channels.', requestedGuild) |
||||
ELSE format('This guild (ID %) is not known to the system.', requestedGuild) |
||||
END, |
||||
HINT = 'As admin commands are normally only visible when a guild allows them, ' || |
||||
'this guild may have been removed from the system incorrectly. ' || |
||||
'Ask an admin to check what''s going on.'; |
||||
END IF; |
||||
END IF; |
||||
END; |
||||
$$ LANGUAGE 'plpgsql'; |
||||
|
||||
--- Gets the list of genders that can be used to register and their corresponding IDs. |
||||
CREATE OR REPLACE FUNCTION GetRegisterableGenders( |
||||
OUT id Gender.id%TYPE, |
||||
OUT name Gender.name%TYPE) |
||||
RETURNS SETOF RECORD |
||||
STRICT |
||||
STABLE |
||||
AS |
||||
$$ |
||||
SELECT Gender.id, Gender.name |
||||
FROM Gender |
||||
$$ |
||||
LANGUAGE 'sql'; |
||||
|
||||
--- Updates a Discord user's username and discriminator, as well as their last active timestamp. |
||||
--- Creates the DiscordUser if they weren't previously recorded in the system. |
||||
CREATE OR REPLACE FUNCTION GetInvokingDiscordUser( |
||||
IN forId DiscordUser.discordId%TYPE, |
||||
IN newUsername DiscordUser.username%TYPE, |
||||
IN newDiscriminator DiscordUser.discriminator%TYPE) |
||||
RETURNS DiscordUser |
||||
STRICT |
||||
STABLE |
||||
AS |
||||
$$ |
||||
INSERT INTO DiscordUser (discordId, username, discriminator, lastActive) |
||||
VALUES (forId, newUsername, newDiscriminator, NOW()) |
||||
ON CONFLICT (discordId) DO UPDATE SET username = newUsername, |
||||
discriminator = newDiscriminator, |
||||
lastActive = NOW() |
||||
RETURNING * |
||||
$$ |
||||
LANGUAGE 'sql'; |
||||
|
||||
--- Gets (and updates the lastActive timestamps of) the player corresponding to the Discord user given by ID. |
||||
--- If such a player does not exist, NULL will be returned and changes will only be made to the DiscordUser table. |
||||
CREATE OR REPLACE FUNCTION GetInvokingPlayer( |
||||
IN forId DiscordUser.discordId%TYPE, |
||||
IN newUsername DiscordUser.username%TYPE, |
||||
IN newDiscriminator DiscordUser.discriminator%TYPE) |
||||
RETURNS Player |
||||
STRICT |
||||
STABLE |
||||
AS |
||||
$$ |
||||
UPDATE Player |
||||
SET lastActive = NOW() |
||||
FROM GetInvokingDiscordUser(forId, newUsername, newDiscriminator) AS InvokingDiscordUser |
||||
WHERE id = InvokingDiscordUser.playerId |
||||
RETURNING ROW (Player.*) |
||||
$$ LANGUAGE 'sql'; |
||||
|
||||
--- Adds a new player, or updates the existing player's name and gender. |
||||
CREATE OR REPLACE FUNCTION UpdatePlayerRegistration( |
||||
IN forId DiscordUser.discordId%TYPE, |
||||
IN newUsername DiscordUser.username%TYPE, |
||||
IN newDiscriminator DiscordUser.discriminator%TYPE, |
||||
IN newPlayerName Player.name%TYPE, |
||||
IN newGenderId Gender.id%TYPE, |
||||
OUT resultId Player.id%TYPE, |
||||
OUT wasCreated BOOLEAN) |
||||
RETURNS RECORD |
||||
STRICT |
||||
STABLE |
||||
AS |
||||
$$ |
||||
DECLARE |
||||
playerId Player.id%TYPE; |
||||
BEGIN |
||||
SELECT InvokingDiscordUser.playerId |
||||
INTO STRICT playerId |
||||
FROM GetInvokingDiscordUser(forId, newUsername, newDiscriminator) |
||||
AS InvokingDiscordUser; |
||||
IF playerId IS NOT NULL THEN |
||||
wasCreated = FALSE; |
||||
UPDATE Player |
||||
SET name = newPlayerName, |
||||
genderId = newGenderId, |
||||
lastActive = NOW() |
||||
WHERE id = playerId |
||||
RETURNING id INTO resultId; |
||||
ELSE |
||||
wasCreated = TRUE; |
||||
INSERT INTO Player (name, genderId, currency, joinedAt, lastActive) |
||||
VALUES (newPlayerName, newGenderId, 100, NOW(), NOW()) |
||||
RETURNING id INTO resultId; |
||||
END IF; |
||||
END; |
||||
$$ |
||||
LANGUAGE 'plpgsql'; |
||||
|
||||
--- Removes the link between a DiscordUser and their Player. |
||||
--- Returns the previous player if one existed, or NULL if not. |
||||
CREATE OR REPLACE FUNCTION UnlinkDiscordUserFromPlayer( |
||||
IN forId DiscordUser.discordId%TYPE, |
||||
IN newUsername DiscordUser.username%TYPE, |
||||
IN newDiscriminator DiscordUser.discriminator%TYPE) |
||||
RETURNS Player.id%TYPE |
||||
STRICT |
||||
STABLE |
||||
AS |
||||
$$ |
||||
DECLARE |
||||
oldPlayerId Player.id%TYPE = NULL; |
||||
BEGIN |
||||
SELECT playerId |
||||
INTO oldPlayerId |
||||
FROM GetInvokingDiscordUser(forId, newUsername, newDiscriminator); |
||||
|
||||
IF oldPlayerId IS NULL THEN |
||||
RETURN NULL; |
||||
END IF; |
||||
|
||||
UPDATE DiscordUser |
||||
SET playerId = NULL |
||||
WHERE discordId = forId; |
||||
|
||||
RETURN oldPlayerId; |
||||
END; |
||||
|
||||
$$ |
||||
LANGUAGE 'plpgsql'; |
||||
|
||||
--- Runs the full /join command. |
||||
--- Error codes: |
||||
--- VGBCG: Bad channel (game). This is not a valid channel to send game commands in. |
||||
--- VGBGG: Bad guild (game). This is not a valid guild to send game commands in. |
||||
CREATE OR REPLACE FUNCTION Command_Join( |
||||
IN requestedChannel DiscordChannel.DiscordId%TYPE, |
||||
IN requestedGuild DiscordChannel.GuildId%TYPE, |
||||
IN forId DiscordUser.discordId%TYPE, |
||||
IN newUsername DiscordUser.username%TYPE, |
||||
IN newDiscriminator DiscordUser.discriminator%TYPE, |
||||
IN newPlayerName Player.name%TYPE, |
||||
IN newGenderId Gender.id%TYPE, |
||||
OUT resultId Player.id%TYPE, |
||||
OUT newPlayerName Player.name%TYPE, |
||||
OUT newGenderName Gender.name%TYPE, |
||||
OUT wasCreated BOOLEAN |
||||
) |
||||
RETURNS RECORD |
||||
STRICT |
||||
STABLE |
||||
AS |
||||
$$ |
||||
CALL CheckGameCommandIn(requestedChannel, requestedGuild); |
||||
|
||||
SELECT NewRegistration.resultId, Player.name, Gender.name, NewRegistration.wasCreated |
||||
FROM UpdatePlayerRegistration(forId, newUsername, newDiscriminator, newPlayerName, newGenderId) AS NewRegistration |
||||
INNER JOIN Player ON Player.id = NewRegistration.resultId |
||||
INNER JOIN Gender ON Gender.id = Player.genderId |
||||
$$ |
||||
LANGUAGE 'sql'; |
||||
|
||||
--- Runs the full /unjoin command. |
||||
--- Error codes: |
||||
--- VGBCG: Bad channel (game). This is not a valid channel to send game commands in. |
||||
--- VGBGG: Bad guild (game). This is not a valid guild to send game commands in. |
||||
CREATE OR REPLACE FUNCTION Command_Unjoin( |
||||
IN requestedChannel DiscordChannel.DiscordId%TYPE, |
||||
IN requestedGuild DiscordChannel.GuildId%TYPE, |
||||
IN forId DiscordUser.discordId%TYPE, |
||||
IN newUsername DiscordUser.username%TYPE, |
||||
IN newDiscriminator DiscordUser.discriminator%TYPE |
||||
) |
||||
RETURNS Player.id%TYPE |
||||
STRICT |
||||
STABLE |
||||
AS |
||||
$$ |
||||
CALL CheckGameCommandIn(requestedChannel, requestedGuild); |
||||
|
||||
SELECT UnlinkDiscordUserFromPlayer(forId, newUsername, newDiscriminator) |
||||
$$ |
||||
LANGUAGE 'sql'; |
@ -0,0 +1,6 @@ |
||||
--! Previous: sha1:d45df95e7f3a77f0a9f7a8bfc6a93cfbebc1c61e |
||||
--! Hash: sha1:c1cb70e8c0dfc171d8f21abb14f503e47fb891bc |
||||
--! Message: fix webhookToken size |
||||
|
||||
ALTER TABLE DiscordChannel |
||||
ALTER COLUMN webhookToken TYPE VARCHAR(128); |
@ -0,0 +1,10 @@ |
||||
--! Previous: sha1:c1cb70e8c0dfc171d8f21abb14f503e47fb891bc |
||||
--! Hash: sha1:c549ad6cc4dc88d928043916e2696eeed3efa420 |
||||
--! Message: fix function volatility |
||||
|
||||
ALTER FUNCTION Command_Join(varchar, varchar, varchar, varchar, varchar, varchar, varchar) VOLATILE; |
||||
ALTER FUNCTION Command_Unjoin(varchar, varchar, varchar, varchar, varchar) VOLATILE; |
||||
ALTER FUNCTION GetInvokingDiscordUser(varchar, varchar, varchar) VOLATILE; |
||||
ALTER FUNCTION GetInvokingPlayer(varchar, varchar, varchar) VOLATILE; |
||||
ALTER FUNCTION UpdatePlayerRegistration(varchar, varchar, varchar, varchar, varchar) VOLATILE; |
||||
ALTER FUNCTION UnlinkDiscordUserFromPlayer(varchar, varchar, varchar) VOLATILE; |
@ -0,0 +1,197 @@ |
||||
--! Previous: sha1:c549ad6cc4dc88d928043916e2696eeed3efa420 |
||||
--! Hash: sha1:defb8b93ce936f1bb553abb90aaa6ecd5a00b1bc |
||||
--! Message: Fix some more procedures |
||||
|
||||
--- Gets whether the users may use game commands in the current channel/guild. |
||||
--- Error codes: |
||||
--- VGBCG: Bad channel (game). This is not a valid channel to send game commands in. |
||||
--- VGBGG: Bad guild (game). This is not a valid guild to send game commands in. |
||||
CREATE OR REPLACE PROCEDURE CheckGameCommandIn( |
||||
IN requestedChannel DiscordChannel.DiscordId%TYPE, |
||||
IN requestedGuild DiscordChannel.GuildId%TYPE) |
||||
AS |
||||
$$ |
||||
DECLARE |
||||
channelAcceptsGameCommands BOOLEAN; |
||||
channelAcceptsAdminCommands BOOLEAN; |
||||
channelSendsMessages BOOLEAN; |
||||
channelIsKnown BOOLEAN; |
||||
guildSupportsGameCommands BOOLEAN; |
||||
guildSupportsAdminCommands BOOLEAN; |
||||
guildSupportsMessages BOOLEAN; |
||||
guildIsKnown BOOLEAN; |
||||
recommendedChannelId DiscordChannel.DiscordId%TYPE; |
||||
BEGIN |
||||
SELECT acceptGameCommands, acceptAdminCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO channelAcceptsGameCommands, channelAcceptsAdminCommands, channelSendsMessages, channelIsKnown |
||||
FROM DiscordChannel |
||||
WHERE discordId = requestedChannel |
||||
LIMIT 1; |
||||
IF channelAcceptsGameCommands IS NOT TRUE THEN |
||||
SELECT discordId, acceptGameCommands, acceptAdminCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO recommendedChannelId, guildSupportsGameCommands, guildSupportsAdminCommands, guildSupportsMessages, guildIsKnown |
||||
FROM DiscordChannel |
||||
WHERE guildId = requestedGuild |
||||
ORDER BY CASE TRUE |
||||
WHEN acceptGameCommands THEN 3 |
||||
WHEN acceptAdminCommands THEN 2 |
||||
WHEN broadcastGame OR sendLogs THEN 1 |
||||
ELSE 0 |
||||
END DESC, priority DESC |
||||
LIMIT 1; |
||||
IF guildSupportsGameCommands IS TRUE THEN |
||||
RAISE EXCEPTION 'Can''t use game commands in this channel' USING |
||||
ERRCODE = 'VGBCG', |
||||
DETAIL = CASE TRUE |
||||
WHEN channelAcceptsGameCommands THEN format( |
||||
'This channel (<#%s>) can only be used to send admin commands, not game commands.', |
||||
requestedChannel) |
||||
WHEN channelSendsMessages THEN format( |
||||
'This channel (<#%s>) is only used to receive broadcasts, not send commands.', |
||||
requestedChannel) |
||||
WHEN channelIsKnown THEN format( |
||||
'This channel (<#%s>) is unused.', requestedChannel) |
||||
ELSE format('This channel (<#%s>) is not known to the system.', requestedChannel) |
||||
END, |
||||
HINT = format( |
||||
'Try sending messages to the channel <#%s> in this guild, which does allow game commands.', |
||||
recommendedChannelId); |
||||
ELSE |
||||
RAISE EXCEPTION 'Can''t use game commands in this guild' USING |
||||
ERRCODE = 'VGBGG', |
||||
DETAIL = CASE TRUE |
||||
WHEN guildSupportsAdminCommands THEN |
||||
format('This guild (ID %) only has channels used to send admin commands, ' || |
||||
'not game commands.', requestedGuild) |
||||
WHEN guildSupportsMessages THEN |
||||
format('This guild (ID %) only has channels used to receive broadcasts, ' || |
||||
'not send commands.', requestedGuild) |
||||
WHEN guildIsKnown THEN |
||||
format('This guild (ID %) only has unused channels.', requestedGuild) |
||||
ELSE format('This guild (ID %) is not known to the system.', requestedGuild) |
||||
END, |
||||
HINT = 'As game commands are normally only visible when a guild allows them, ' || |
||||
'this guild may have been removed from the system incorrectly. ' || |
||||
'Ask an admin to check what''s going on.'; |
||||
END IF; |
||||
END IF; |
||||
END; |
||||
$$ LANGUAGE 'plpgsql'; |
||||
|
||||
--- Gets whether the users may use admin commands in the current channel/guild. |
||||
--- Error codes: |
||||
--- VGBCA: Bad channel (admin). This is not a valid channel to send admin commands in. |
||||
--- VGBGA: Bad guild (admin). This is not a valid guild to send admin commands in. |
||||
CREATE OR REPLACE PROCEDURE CheckAdminCommandIn( |
||||
IN requestedChannel DiscordChannel.DiscordId%TYPE, |
||||
IN requestedGuild DiscordChannel.GuildId%TYPE) |
||||
AS |
||||
$$ |
||||
DECLARE |
||||
channelAcceptsAdminCommands BOOLEAN; |
||||
channelAcceptsGameCommands BOOLEAN; |
||||
channelSendsMessages BOOLEAN; |
||||
channelIsKnown BOOLEAN; |
||||
guildSupportsAdminCommands BOOLEAN; |
||||
guildSupportsGameCommands BOOLEAN; |
||||
guildSupportsMessages BOOLEAN; |
||||
guildIsKnown BOOLEAN; |
||||
recommendedChannelId DiscordChannel.DiscordId%TYPE; |
||||
BEGIN |
||||
SELECT acceptAdminCommands, acceptGameCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO channelAcceptsAdminCommands, channelAcceptsGameCommands, channelSendsMessages, channelIsKnown |
||||
FROM DiscordChannel |
||||
WHERE discordId = requestedChannel |
||||
LIMIT 1; |
||||
IF channelAcceptsAdminCommands IS NOT TRUE THEN |
||||
SELECT discordId, acceptAdminCommands, acceptGameCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO recommendedChannelId, guildSupportsAdminCommands, guildSupportsGameCommands, guildSupportsMessages, guildIsKnown |
||||
FROM DiscordChannel |
||||
WHERE guildId = requestedGuild |
||||
ORDER BY CASE TRUE |
||||
WHEN acceptAdminCommands THEN 3 |
||||
WHEN acceptGameCommands THEN 2 |
||||
WHEN broadcastGame OR sendLogs THEN 1 |
||||
ELSE 0 |
||||
END DESC, priority DESC |
||||
LIMIT 1; |
||||
IF guildSupportsAdminCommands IS TRUE THEN |
||||
RAISE EXCEPTION 'Can''t use admin commands in this channel' USING |
||||
ERRCODE = 'VGBCA', |
||||
DETAIL = CASE TRUE |
||||
WHEN channelAcceptsGameCommands THEN format( |
||||
'This channel (<#%s>) can only be used to send admin commands, not game commands.', |
||||
requestedChannel) |
||||
WHEN channelSendsMessages THEN format( |
||||
'This channel (<#%s>) is only used to receive broadcasts, not send commands.', |
||||
requestedChannel) |
||||
WHEN channelIsKnown THEN format( |
||||
'This channel (<#%s>) is unused.', requestedChannel) |
||||
ELSE format('This channel (<#%s>) is not known to the system.', requestedChannel) |
||||
END, |
||||
HINT = format( |
||||
'Try sending messages to the channel <#%s> in this guild, which does allow game commands.', |
||||
recommendedChannelId); |
||||
ELSE |
||||
RAISE EXCEPTION 'Can''t use admin commands in this guild' USING |
||||
ERRCODE = 'VGBGA', |
||||
DETAIL = CASE TRUE |
||||
WHEN guildSupportsGameCommands THEN |
||||
format('This guild (ID %s) only has channels used to send game commands, ' || |
||||
'not admin commands.', requestedGuild) |
||||
WHEN guildSupportsMessages THEN |
||||
format('This guild (ID %s) only has channels used to receive broadcasts, ' || |
||||
'not send commands.', requestedGuild) |
||||
WHEN guildIsKnown THEN |
||||
format('This guild (ID %s) only has unused channels.', requestedGuild) |
||||
ELSE format('This guild (ID %s) is not known to the system.', requestedGuild) |
||||
END, |
||||
HINT = 'As admin commands are normally only visible when a guild allows them, ' || |
||||
'this guild may have been removed from the system incorrectly. ' || |
||||
'Ask an admin to check what''s going on.'; |
||||
END IF; |
||||
END IF; |
||||
END; |
||||
$$ LANGUAGE 'plpgsql'; |
||||
|
||||
--- Adds a new player, or updates the existing player's name and gender. |
||||
CREATE OR REPLACE FUNCTION UpdatePlayerRegistration( |
||||
IN forId DiscordUser.discordId%TYPE, |
||||
IN newUsername DiscordUser.username%TYPE, |
||||
IN newDiscriminator DiscordUser.discriminator%TYPE, |
||||
IN newPlayerName Player.name%TYPE, |
||||
IN newGenderId Gender.id%TYPE, |
||||
OUT resultId Player.id%TYPE, |
||||
OUT wasCreated BOOLEAN) |
||||
RETURNS RECORD |
||||
STRICT |
||||
VOLATILE |
||||
AS |
||||
$$ |
||||
DECLARE |
||||
playerId Player.id%TYPE; |
||||
BEGIN |
||||
SELECT InvokingDiscordUser.playerId |
||||
INTO STRICT playerId |
||||
FROM GetInvokingDiscordUser(forId, newUsername, newDiscriminator) |
||||
AS InvokingDiscordUser; |
||||
IF playerId IS NOT NULL THEN |
||||
wasCreated = FALSE; |
||||
UPDATE Player |
||||
SET name = newPlayerName, |
||||
genderId = newGenderId, |
||||
lastActive = NOW() |
||||
WHERE id = playerId |
||||
RETURNING id INTO resultId; |
||||
ELSE |
||||
wasCreated = TRUE; |
||||
INSERT INTO Player (name, genderId, currency, joinedAt, lastActive) |
||||
VALUES (newPlayerName, newGenderId, 100, NOW(), NOW()) |
||||
RETURNING id INTO resultId; |
||||
UPDATE DiscordUser |
||||
SET playerId = resultId |
||||
WHERE discordId = forId; |
||||
END IF; |
||||
END; |
||||
$$ |
||||
LANGUAGE 'plpgsql'; |
@ -0,0 +1,33 @@ |
||||
--! Previous: sha1:defb8b93ce936f1bb553abb90aaa6ecd5a00b1bc |
||||
--! Hash: sha1:00899815dc03fa792300ff69dde9d17756448635 |
||||
--! Message: Fix Command_Join again |
||||
|
||||
--- Runs the full /join command. |
||||
--- Error codes: |
||||
--- VGBCG: Bad channel (game). This is not a valid channel to send game commands in. |
||||
--- VGBGG: Bad guild (game). This is not a valid guild to send game commands in. |
||||
CREATE OR REPLACE FUNCTION Command_Join( |
||||
IN requestedChannel DiscordChannel.DiscordId%TYPE, |
||||
IN requestedGuild DiscordChannel.GuildId%TYPE, |
||||
IN forId DiscordUser.discordId%TYPE, |
||||
IN newUsername DiscordUser.username%TYPE, |
||||
IN newDiscriminator DiscordUser.discriminator%TYPE, |
||||
IN newPlayerName Player.name%TYPE, |
||||
IN newGenderId Gender.id%TYPE, |
||||
OUT resultId Player.id%TYPE, |
||||
OUT newPlayerName Player.name%TYPE, |
||||
OUT newGenderName Gender.name%TYPE, |
||||
OUT wasCreated BOOLEAN |
||||
) |
||||
RETURNS RECORD |
||||
STRICT |
||||
VOLATILE |
||||
AS |
||||
$$ |
||||
CALL CheckGameCommandIn(requestedChannel, requestedGuild); |
||||
|
||||
SELECT NewRegistration.resultId, newPlayerName, Gender.name, NewRegistration.wasCreated |
||||
FROM UpdatePlayerRegistration(forId, newUsername, newDiscriminator, newPlayerName, newGenderId) AS NewRegistration |
||||
LEFT JOIN Gender ON Gender.id = newGenderId |
||||
$$ |
||||
LANGUAGE 'sql'; |
@ -0,0 +1,66 @@ |
||||
--! Previous: sha1:00899815dc03fa792300ff69dde9d17756448635 |
||||
--! Hash: sha1:e7ff9a64813ea9e0a701219f6b2ba8ed88dcf240 |
||||
--! Message: pull command skeleton |
||||
|
||||
--- Runs the full /pull command. |
||||
--- Error codes: |
||||
--- VGBCG: Bad channel (game). This is not a valid channel to send game commands in. |
||||
--- VGBGG: Bad guild (game). This is not a valid guild to send game commands in. |
||||
--- VGNYJ: Not yet joined. The Discord user using has not joined the game yet. |
||||
--- VGNEC: Not enough currency. |
||||
CREATE OR REPLACE FUNCTION Command_Pull( |
||||
IN requestedChannel DiscordChannel.discordId%TYPE, |
||||
IN requestedGuild DiscordChannel.guildId%TYPE, |
||||
IN forId DiscordUser.discordId%TYPE, |
||||
IN newUsername DiscordUser.username%TYPE, |
||||
IN newDiscriminator DiscordUser.discriminator%TYPE, |
||||
IN count INT |
||||
) |
||||
RETURNS TABLE |
||||
( |
||||
summonedUnitInstanceId SummonedUnit.instanceId%TYPE, |
||||
summonedUnitId Unit.id%TYPE, |
||||
summonedUnitName Unit.name%TYPE, |
||||
summonedUnitSubtitle Unit.subtitle%TYPE, |
||||
summonedUnitTierName UnitTier.name%TYPE, |
||||
firstTimePull BOOLEAN, |
||||
wasAlreadySummoned BOOLEAN |
||||
) |
||||
STRICT |
||||
VOLATILE |
||||
ROWS 10 |
||||
AS |
||||
$$ |
||||
DECLARE |
||||
playerId Player.id%TYPE; |
||||
cost Player.currency%TYPE; |
||||
oldCurrency Player.currency%TYPE; |
||||
playerLastDaily Player.lastDaily%TYPE; |
||||
BEGIN |
||||
CALL CheckGameCommandIn(requestedChannel, requestedGuild); |
||||
SELECT InvokingPlayer.id, InvokingPlayer.currency, InvokingPlayer.lastDaily |
||||
INTO playerId, oldCurrency, playerLastDaily |
||||
FROM GetInvokingPlayer(forId, newUsername, newDiscriminator) AS InvokingPlayer; |
||||
IF playerId IS NULL THEN |
||||
RAISE EXCEPTION USING |
||||
ERRCODE = 'VGNYJ', |
||||
MESSAGE = 'Not yet joined', |
||||
DETAIL = 'You haven''t joined the game yet, and can''t use this command until you do.', |
||||
HINT = 'Use the /join command to join the game!'; |
||||
END IF; |
||||
cost = 10 * count; |
||||
UPDATE Player SET currency = currency - cost WHERE id = playerId AND currency >= cost; |
||||
IF NOT FOUND THEN |
||||
RAISE EXCEPTION USING |
||||
ERRCODE = 'VGNEC', |
||||
MESSAGE = 'Not enough currency', |
||||
DETAIL = format('Pulling %s heroines would cost %s currency, but you only have %s currency.', |
||||
count, cost, oldCurrency), |
||||
HINT = CASE playerLastDaily IS NULL OR playerLastDaily < NOW() - '1 day'::interval |
||||
WHEN TRUE THEN 'Try using the /daily command to get some more currency for today!' |
||||
ELSE format('Wait %s and you can use the /daily command to get some more currency!', |
||||
(playerLastDaily + '1 day'::interval) - NOW()) |
||||
END; |
||||
END IF; |
||||
END; |
||||
$$ LANGUAGE 'plpgsql'; |
@ -0,0 +1,542 @@ |
||||
create table if not exists discordchannel |
||||
( |
||||
discordid varchar(20) not null |
||||
constraint discordchannel_pkey |
||||
primary key, |
||||
name varchar(100) not null, |
||||
broadcastgame boolean default false not null, |
||||
sendlogs boolean default false not null, |
||||
acceptgamecommands boolean default false not null, |
||||
acceptadmincommands boolean default false not null, |
||||
priority smallint default 0 not null, |
||||
guildid varchar(20) default NULL::character varying, |
||||
webhookid varchar(20) default NULL::character varying, |
||||
webhooktoken varchar(128) default NULL::character varying, |
||||
constraint discordchannel_webhookpair |
||||
check (((webhookid IS NULL) AND (webhooktoken IS NULL)) OR |
||||
((webhookid IS NOT NULL) AND (webhooktoken IS NOT NULL))) |
||||
); |
||||
|
||||
alter table discordchannel |
||||
owner to gacha; |
||||
|
||||
create index if not exists discordchannel_guildid |
||||
on discordchannel (guildid) |
||||
where (guildid IS NOT NULL); |
||||
|
||||
create index if not exists discordchannel_acceptsgamecommands |
||||
on discordchannel (acceptgamecommands) |
||||
where (acceptgamecommands IS TRUE); |
||||
|
||||
create index if not exists discordchannel_acceptsadmincommands |
||||
on discordchannel (acceptadmincommands) |
||||
where (acceptadmincommands IS TRUE); |
||||
|
||||
create table if not exists gender |
||||
( |
||||
id varchar(8) not null |
||||
constraint gender_pkey |
||||
primary key, |
||||
name varchar(100) not null |
||||
constraint gender_name_key |
||||
unique |
||||
); |
||||
|
||||
alter table gender |
||||
owner to gacha; |
||||
|
||||
create table if not exists player |
||||
( |
||||
id serial |
||||
constraint player_pkey |
||||
primary key, |
||||
name varchar(100) not null, |
||||
genderid varchar(8) not null |
||||
constraint player_genderid_fkey |
||||
references gender |
||||
on update cascade on delete restrict, |
||||
currency integer not null, |
||||
joinedat timestamp with time zone default now() not null, |
||||
lastactive timestamp with time zone default now() not null, |
||||
lastdaily timestamp with time zone |
||||
); |
||||
|
||||
alter table player |
||||
owner to gacha; |
||||
|
||||
create table if not exists discorduser |
||||
( |
||||
discordid varchar(20) not null |
||||
constraint discorduser_pkey |
||||
primary key, |
||||
username varchar(32) not null, |
||||
discriminator varchar(4) not null, |
||||
playerid integer |
||||
constraint discorduser_playerid_fkey |
||||
references player |
||||
on update cascade on delete set null, |
||||
lastactive timestamp with time zone default now() not null |
||||
); |
||||
|
||||
alter table discorduser |
||||
owner to gacha; |
||||
|
||||
create table if not exists unittier |
||||
( |
||||
id varchar(8) not null |
||||
constraint unittier_pkey |
||||
primary key, |
||||
name varchar(100) not null |
||||
constraint unittier_name_key |
||||
unique, |
||||
pullweight integer not null, |
||||
recallcost integer not null |
||||
); |
||||
|
||||
alter table unittier |
||||
owner to gacha; |
||||
|
||||
create table if not exists unit |
||||
( |
||||
id serial |
||||
constraint unit_pkey |
||||
primary key, |
||||
name varchar(50) not null, |
||||
subtitle varchar(50) not null, |
||||
description text not null, |
||||
tierid varchar(8) not null |
||||
constraint unit_tierid_fkey |
||||
references unittier |
||||
on update cascade on delete restrict, |
||||
basehealth integer not null |
||||
constraint unit_basehealth_check |
||||
check (basehealth > 0), |
||||
basestrength integer not null |
||||
constraint unit_basestrength_check |
||||
check (basestrength > 0), |
||||
constraint unit_name_subtitle_key |
||||
unique (name, subtitle) |
||||
); |
||||
|
||||
alter table unit |
||||
owner to gacha; |
||||
|
||||
create table if not exists summonedunit |
||||
( |
||||
instanceid serial |
||||
constraint summonedunit_pkey |
||||
primary key, |
||||
playerid integer not null |
||||
constraint summonedunit_playerid_fkey |
||||
references player |
||||
on update cascade on delete cascade, |
||||
unitid integer not null |
||||
constraint summonedunit_unitid_fkey |
||||
references unit |
||||
on update cascade on delete cascade, |
||||
summonedat timestamp with time zone default now() not null, |
||||
waspulled boolean default false not null, |
||||
wasrecalled boolean default false not null, |
||||
resummonings timestamp with time zone[], |
||||
desummonedat timestamp with time zone, |
||||
digestedbyinstanceid integer |
||||
constraint summonedunit_digestedbyinstanceid_fkey |
||||
references summonedunit |
||||
on update cascade on delete set null, |
||||
wasdigested boolean, |
||||
wasreleased boolean, |
||||
currenthealth integer not null, |
||||
maxhealth integer not null |
||||
constraint summonedunit_maxhealth_check |
||||
check (maxhealth > 0), |
||||
strength integer not null |
||||
constraint summonedunit_strength_check |
||||
check (strength > 0), |
||||
constraint summonedunit_currenthealthbounds |
||||
check ((currenthealth >= (- maxhealth)) AND (currenthealth <= maxhealth)), |
||||
constraint summonedunit_exactlyoneorigin |
||||
check (((waspulled IS TRUE) OR (wasrecalled IS TRUE)) AND |
||||
(NOT ((waspulled IS FALSE) AND (wasrecalled IS FALSE)))), |
||||
constraint summonedunit_exactlyonefate |
||||
check ((((wasdigested IS TRUE) OR (wasreleased IS TRUE)) = (desummonedat IS NOT NULL)) AND |
||||
(((wasdigested IS NULL) OR (wasreleased IS NULL)) = (desummonedat IS NULL))), |
||||
constraint summonedunit_digesterfordigestedonly |
||||
check ((digestedbyinstanceid IS NULL) OR (wasdigested IS TRUE)) |
||||
); |
||||
|
||||
alter table summonedunit |
||||
owner to gacha; |
||||
|
||||
create unique index if not exists summonedunit_oneinstanceperunitperplayer |
||||
on summonedunit (playerid, unitid) |
||||
where (desummonedat IS NULL); |
||||
|
||||
create or replace function getguildidsabletousegamecommands() returns SETOF character varying |
||||
stable |
||||
rows 1 |
||||
language sql |
||||
as |
||||
$$ |
||||
SELECT DISTINCT guildId |
||||
FROM DiscordChannel |
||||
WHERE guildId IS NOT NULL |
||||
AND acceptGameCommands IS TRUE; |
||||
$$; |
||||
|
||||
alter function getguildidsabletousegamecommands() owner to gacha; |
||||
|
||||
create or replace procedure checkgamecommandin(requestedchannel character varying, requestedguild character varying) |
||||
language plpgsql |
||||
as |
||||
$$ |
||||
DECLARE |
||||
channelAcceptsGameCommands BOOLEAN; |
||||
channelAcceptsAdminCommands BOOLEAN; |
||||
channelSendsMessages BOOLEAN; |
||||
channelIsKnown BOOLEAN; |
||||
guildSupportsGameCommands BOOLEAN; |
||||
guildSupportsAdminCommands BOOLEAN; |
||||
guildSupportsMessages BOOLEAN; |
||||
guildIsKnown BOOLEAN; |
||||
recommendedChannelId DiscordChannel.DiscordId%TYPE; |
||||
BEGIN |
||||
SELECT acceptGameCommands, acceptAdminCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO channelAcceptsGameCommands, channelAcceptsAdminCommands, channelSendsMessages, channelIsKnown |
||||
FROM DiscordChannel |
||||
WHERE discordId = requestedChannel |
||||
LIMIT 1; |
||||
IF channelAcceptsGameCommands IS NOT TRUE THEN |
||||
SELECT discordId, acceptGameCommands, acceptAdminCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO recommendedChannelId, guildSupportsGameCommands, guildSupportsAdminCommands, guildSupportsMessages, guildIsKnown |
||||
FROM DiscordChannel |
||||
WHERE guildId = requestedGuild |
||||
ORDER BY CASE TRUE |
||||
WHEN acceptGameCommands THEN 3 |
||||
WHEN acceptAdminCommands THEN 2 |
||||
WHEN broadcastGame OR sendLogs THEN 1 |
||||
ELSE 0 |
||||
END DESC, priority DESC |
||||
LIMIT 1; |
||||
IF guildSupportsGameCommands IS TRUE THEN |
||||
RAISE EXCEPTION 'Can''t use game commands in this channel' USING |
||||
ERRCODE = 'VGBCG', |
||||
DETAIL = CASE TRUE |
||||
WHEN channelAcceptsGameCommands THEN format( |
||||
'This channel (<#%s>) can only be used to send admin commands, not game commands.', |
||||
requestedChannel) |
||||
WHEN channelSendsMessages THEN format( |
||||
'This channel (<#%s>) is only used to receive broadcasts, not send commands.', |
||||
requestedChannel) |
||||
WHEN channelIsKnown THEN format( |
||||
'This channel (<#%s>) is unused.', requestedChannel) |
||||
ELSE format('This channel (<#%s>) is not known to the system.', requestedChannel) |
||||
END, |
||||
HINT = format( |
||||
'Try sending messages to the channel <#%s> in this guild, which does allow game commands.', |
||||
recommendedChannelId); |
||||
ELSE |
||||
RAISE EXCEPTION 'Can''t use game commands in this guild' USING |
||||
ERRCODE = 'VGBGG', |
||||
DETAIL = CASE TRUE |
||||
WHEN guildSupportsAdminCommands THEN |
||||
format('This guild (ID %) only has channels used to send admin commands, ' || |
||||
'not game commands.', requestedGuild) |
||||
WHEN guildSupportsMessages THEN |
||||
format('This guild (ID %) only has channels used to receive broadcasts, ' || |
||||
'not send commands.', requestedGuild) |
||||
WHEN guildIsKnown THEN |
||||
format('This guild (ID %) only has unused channels.', requestedGuild) |
||||
ELSE format('This guild (ID %) is not known to the system.', requestedGuild) |
||||
END, |
||||
HINT = 'As game commands are normally only visible when a guild allows them, ' || |
||||
'this guild may have been removed from the system incorrectly. ' || |
||||
'Ask an admin to check what''s going on.'; |
||||
END IF; |
||||
END IF; |
||||
END; |
||||
$$; |
||||
|
||||
alter procedure checkgamecommandin(varchar, varchar) owner to gacha; |
||||
|
||||
create or replace function getguildidsabletouseadmincommands() returns SETOF character varying |
||||
stable |
||||
rows 1 |
||||
language sql |
||||
as |
||||
$$ |
||||
SELECT DISTINCT guildId |
||||
FROM DiscordChannel |
||||
WHERE guildId IS NOT NULL |
||||
AND acceptAdminCommands IS TRUE; |
||||
$$; |
||||
|
||||
alter function getguildidsabletouseadmincommands() owner to gacha; |
||||
|
||||
create or replace procedure checkadmincommandin(requestedchannel character varying, requestedguild character varying) |
||||
language plpgsql |
||||
as |
||||
$$ |
||||
DECLARE |
||||
channelAcceptsAdminCommands BOOLEAN; |
||||
channelAcceptsGameCommands BOOLEAN; |
||||
channelSendsMessages BOOLEAN; |
||||
channelIsKnown BOOLEAN; |
||||
guildSupportsAdminCommands BOOLEAN; |
||||
guildSupportsGameCommands BOOLEAN; |
||||
guildSupportsMessages BOOLEAN; |
||||
guildIsKnown BOOLEAN; |
||||
recommendedChannelId DiscordChannel.DiscordId%TYPE; |
||||
BEGIN |
||||
SELECT acceptAdminCommands, acceptGameCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO channelAcceptsAdminCommands, channelAcceptsGameCommands, channelSendsMessages, channelIsKnown |
||||
FROM DiscordChannel |
||||
WHERE discordId = requestedChannel |
||||
LIMIT 1; |
||||
IF channelAcceptsAdminCommands IS NOT TRUE THEN |
||||
SELECT discordId, acceptAdminCommands, acceptGameCommands, broadcastGame OR sendLogs, TRUE |
||||
INTO recommendedChannelId, guildSupportsAdminCommands, guildSupportsGameCommands, guildSupportsMessages, guildIsKnown |
||||
FROM DiscordChannel |
||||
WHERE guildId = requestedGuild |
||||
ORDER BY CASE TRUE |
||||
WHEN acceptAdminCommands THEN 3 |
||||
WHEN acceptGameCommands THEN 2 |
||||
WHEN broadcastGame OR sendLogs THEN 1 |
||||
ELSE 0 |
||||
END DESC, priority DESC |
||||
LIMIT 1; |
||||
IF guildSupportsAdminCommands IS TRUE THEN |
||||
RAISE EXCEPTION 'Can''t use admin commands in this channel' USING |
||||
ERRCODE = 'VGBCA', |
||||
DETAIL = CASE TRUE |
||||
WHEN channelAcceptsGameCommands THEN format( |
||||
'This channel (<#%s>) can only be used to send admin commands, not game commands.', |
||||
requestedChannel) |
||||
WHEN channelSendsMessages THEN format( |
||||
'This channel (<#%s>) is only used to receive broadcasts, not send commands.', |
||||
requestedChannel) |
||||
WHEN channelIsKnown THEN format( |
||||
'This channel (<#%s>) is unused.', requestedChannel) |
||||
ELSE format('This channel (<#%s>) is not known to the system.', requestedChannel) |
||||
END, |
||||
HINT = format( |
||||
'Try sending messages to the channel <#%s> in this guild, which does allow game commands.', |
||||
recommendedChannelId); |
||||
ELSE |
||||
RAISE EXCEPTION 'Can''t use admin commands in this guild' USING |
||||
ERRCODE = 'VGBGA', |
||||
DETAIL = CASE TRUE |
||||
WHEN guildSupportsGameCommands THEN |
||||
format('This guild (ID %s) only has channels used to send game commands, ' || |
||||
'not admin commands.', requestedGuild) |
||||
WHEN guildSupportsMessages THEN |
||||
format('This guild (ID %s) only has channels used to receive broadcasts, ' || |
||||
'not send commands.', requestedGuild) |
||||
WHEN guildIsKnown THEN |
||||
format('This guild (ID %s) only has unused channels.', requestedGuild) |
||||
ELSE format('This guild (ID %s) is not known to the system.', requestedGuild) |
||||
END, |
||||
HINT = 'As admin commands are normally only visible when a guild allows them, ' || |
||||
'this guild may have been removed from the system incorrectly. ' || |
||||
'Ask an admin to check what''s going on.'; |
||||
END IF; |
||||
END IF; |
||||
END; |
||||
$$; |
||||
|
||||
alter procedure checkadmincommandin(varchar, varchar) owner to gacha; |
||||
|
||||
create or replace function getregisterablegenders(OUT id character varying, OUT name character varying) returns SETOF record |
||||
stable |
||||
strict |
||||
language sql |
||||
as |
||||
$$ |
||||
SELECT Gender.id, Gender.name |
||||
FROM Gender |
||||
$$; |
||||
|
||||
alter function getregisterablegenders(out varchar, out varchar) owner to gacha; |
||||
|
||||
create or replace function getinvokingdiscorduser(forid character varying, newusername character varying, |
||||
newdiscriminator character varying) returns discorduser |
||||
strict |
||||
language sql |
||||
as |
||||
$$ |
||||
INSERT INTO DiscordUser (discordId, username, discriminator, lastActive) |
||||
VALUES (forId, newUsername, newDiscriminator, NOW()) |
||||
ON CONFLICT (discordId) DO UPDATE SET username = newUsername, |
||||
discriminator = newDiscriminator, |
||||
lastActive = NOW() |
||||
RETURNING * |
||||
$$; |
||||
|
||||
alter function getinvokingdiscorduser(varchar, varchar, varchar) owner to gacha; |
||||
|
||||
create or replace function getinvokingplayer(forid character varying, newusername character varying, |
||||
newdiscriminator character varying) returns player |
||||
strict |
||||
language sql |
||||
as |
||||
$$ |
||||
UPDATE Player |
||||
SET lastActive = NOW() |
||||
FROM GetInvokingDiscordUser(forId, newUsername, newDiscriminator) AS InvokingDiscordUser |
||||
WHERE id = InvokingDiscordUser.playerId |
||||
RETURNING ROW (Player.*) |
||||
$$; |
||||
|
||||
alter function getinvokingplayer(varchar, varchar, varchar) owner to gacha; |
||||
|
||||
create or replace function updateplayerregistration(forid character varying, newusername character varying, |
||||
newdiscriminator character varying, newplayername character varying, |
||||
newgenderid character varying, OUT resultid integer, |
||||
OUT wascreated boolean) returns record |
||||
strict |
||||
language plpgsql |
||||
as |
||||
$$ |
||||
DECLARE |
||||
playerId Player.id%TYPE; |
||||
BEGIN |
||||
SELECT InvokingDiscordUser.playerId |
||||
INTO STRICT playerId |
||||
FROM GetInvokingDiscordUser(forId, newUsername, newDiscriminator) |
||||
AS InvokingDiscordUser; |
||||
IF playerId IS NOT NULL THEN |
||||
wasCreated = FALSE; |
||||
UPDATE Player |
||||
SET name = newPlayerName, |
||||
genderId = newGenderId, |
||||
lastActive = NOW() |
||||
WHERE id = playerId |
||||
RETURNING id INTO resultId; |
||||
ELSE |
||||
wasCreated = TRUE; |
||||
INSERT INTO Player (name, genderId, currency, joinedAt, lastActive) |
||||
VALUES (newPlayerName, newGenderId, 100, NOW(), NOW()) |
||||
RETURNING id INTO resultId; |
||||
UPDATE DiscordUser |
||||
SET playerId = resultId |
||||
WHERE discordId = forId; |
||||
END IF; |
||||
END; |
||||
$$; |
||||
|
||||
alter function updateplayerregistration(varchar, varchar, varchar, varchar, varchar, out integer, out boolean) owner to gacha; |
||||
|
||||
create or replace function unlinkdiscorduserfromplayer(forid character varying, newusername character varying, |
||||
newdiscriminator character varying) returns integer |
||||
strict |
||||
language plpgsql |
||||
as |
||||
$$ |
||||
DECLARE |
||||
oldPlayerId Player.id%TYPE = NULL; |
||||
BEGIN |
||||
SELECT playerId |
||||
INTO oldPlayerId |
||||
FROM GetInvokingDiscordUser(forId, newUsername, newDiscriminator); |
||||
|
||||
IF oldPlayerId IS NULL THEN |
||||
RETURN NULL; |
||||
END IF; |
||||
|
||||
UPDATE DiscordUser |
||||
SET playerId = NULL |
||||
WHERE discordId = forId; |
||||
|
||||
RETURN oldPlayerId; |
||||
END; |
||||
|
||||
$$; |
||||
|
||||
alter function unlinkdiscorduserfromplayer(varchar, varchar, varchar) owner to gacha; |
||||
|
||||
create or replace function command_join(requestedchannel character varying, requestedguild character varying, |
||||
forid character varying, newusername character varying, |
||||
newdiscriminator character varying, newplayername character varying, |
||||
newgenderid character varying, OUT resultid integer, |
||||
OUT newplayername character varying, OUT newgendername character varying, |
||||
OUT wascreated boolean) returns record |
||||
strict |
||||
language sql |
||||
as |
||||
$$ |
||||
CALL CheckGameCommandIn(requestedChannel, requestedGuild); |
||||
|
||||
SELECT NewRegistration.resultId, newPlayerName, Gender.name, NewRegistration.wasCreated |
||||
FROM UpdatePlayerRegistration(forId, newUsername, newDiscriminator, newPlayerName, newGenderId) AS NewRegistration |
||||
LEFT JOIN Gender ON Gender.id = newGenderId |
||||
$$; |
||||
|
||||
alter function command_join(varchar, varchar, varchar, varchar, varchar, varchar, varchar, out integer, out varchar, out varchar, out boolean) owner to gacha; |
||||
|
||||
create or replace function command_unjoin(requestedchannel character varying, requestedguild character varying, |
||||
forid character varying, newusername character varying, |
||||
newdiscriminator character varying) returns integer |
||||
strict |
||||
language sql |
||||
as |
||||
$$ |
||||
CALL CheckGameCommandIn(requestedChannel, requestedGuild); |
||||
|
||||
SELECT UnlinkDiscordUserFromPlayer(forId, newUsername, newDiscriminator) |
||||
$$; |
||||
|
||||
alter function command_unjoin(varchar, varchar, varchar, varchar, varchar) owner to gacha; |
||||
|
||||
create or replace function command_pull(requestedchannel character varying, requestedguild character varying, |
||||
forid character varying, newusername character varying, |
||||
newdiscriminator character varying, count integer) |
||||
returns TABLE |
||||
( |
||||
summonedunitinstanceid integer, |
||||
summonedunitid integer, |
||||
summonedunitname character varying, |
||||
summonedunitsubtitle character varying, |
||||
summonedunittiername character varying, |
||||
firsttimepull boolean, |
||||
wasalreadysummoned boolean |
||||
) |
||||
strict |
||||
rows 10 |
||||
language plpgsql |
||||
as |
||||
$$ |
||||
DECLARE |
||||
playerId Player.id%TYPE; |
||||
cost Player.currency%TYPE; |
||||
oldCurrency Player.currency%TYPE; |
||||
playerLastDaily Player.lastDaily%TYPE; |
||||
BEGIN |
||||
CALL CheckGameCommandIn(requestedChannel, requestedGuild); |
||||
SELECT InvokingPlayer.id, InvokingPlayer.currency, InvokingPlayer.lastDaily |
||||
INTO playerId, oldCurrency, playerLastDaily |
||||
FROM GetInvokingPlayer(forId, newUsername, newDiscriminator) AS InvokingPlayer; |
||||
IF NOT FOUND THEN |
||||
RAISE EXCEPTION USING |
||||
ERRCODE = 'VGNYJ', |
||||
MESSAGE = 'Not yet joined', |
||||
DETAIL = 'You haven''t joined the game yet, and can''t use this command until you do.', |
||||
HINT = 'Use the /join command to join the game!'; |
||||
END IF; |
||||
cost = 10 * count; |
||||
UPDATE Player SET currency = currency - cost WHERE id = playerId AND currency >= cost; |
||||
IF NOT FOUND THEN |
||||
RAISE EXCEPTION USING |
||||
ERRCODE = 'VGNEC', |
||||
MESSAGE = 'Not enough currency', |
||||
DETAIL = format('Pulling %s heroines would cost %s currency, but you only have %s currency.', |
||||
count, cost, oldCurrency), |
||||
HINT = CASE playerLastDaily IS NULL OR playerLastDaily < NOW() - '1 day'::interval |
||||
WHEN TRUE THEN 'Try using the /daily command to get some more currency for today!' |
||||
ELSE format('Wait %s and you can use the /daily command to get some more currency!', |
||||
(playerLastDaily + '1 day'::interval) - NOW()) |
||||
END; |
||||
END IF; |
||||
END; |
||||
$$; |
||||
|
||||
alter function command_pull(varchar, varchar, varchar, varchar, varchar, integer) owner to gacha; |
||||
|
File diff suppressed because it is too large
Load Diff
@ -1,185 +0,0 @@ |
||||
datasource db { |
||||
provider = "sqlite" |
||||
url = "file:../runtime/database/db.sqlite" |
||||
} |
||||
|
||||
generator client { |
||||
provider = "prisma-client-js" |
||||
} |
||||
|
||||
/// Discord channels known to the server. |
||||
model DiscordChannel { |
||||
/// The ID of the channel in Discord. |
||||
discordId String @id |
||||
/// The last known name of this channel. |
||||
name String |
||||
/// True if this channel should be used to broadcast public game events. |
||||
broadcastGame Boolean |
||||
/// True if this channel should be used to send logs. |
||||
sendLogs Boolean |
||||
/// True if this channel can accept game commands. |
||||
acceptGameCommands Boolean |
||||
/// True if this channel can accept admin commands. |
||||
acceptAdminCommands Boolean |
||||
/// The priority of this channel when slowing down to account for rate limits. Higher is more important. |
||||
priority Int |
||||
/// The guild in which this channel exists, if it's known. |
||||
guildId String? |
||||
/// The ID of the webhook used to post to this channel. Deleted if the webhook 404's. |
||||
webhookId String? |
||||
/// The webhook token used to post to this channel. Deleted if the webhook 404's. |
||||
token String? |
||||
} |
||||
|
||||
/// User genders. |
||||
model Gender { |
||||
/// The internal ID associated with this gender. |
||||
id String @id @default(cuid()) |
||||
/// The human-readable name of this gender. Unique among genders. |
||||
name String @unique |
||||
/// The users with this gender. |
||||
User User[] |
||||
} |
||||
|
||||
/// In-game user data structure. |
||||
model User { |
||||
/// The internal ID associated with this account. |
||||
/// It's separate from the Discord ID associated with this account. This supports a few things: |
||||
/// 1) We can move the game off of Discord, or add the ability to play it as a separate phone app or webapp, |
||||
/// without losing our database. |
||||
/// 2) If necessary, we can support having multiple Discord users associated with the same user account, to |
||||
/// support multi-account play. |
||||
/// 3) If necessary, we can support changing the Discord user associated with a user account, if for any reason |
||||
/// they are no longer using the old account and want to switch to a new account. |
||||
id String @id @default(cuid()) |
||||
/// The user's name, for the purposes of the game. This is completely separate from both their username and nickname |
||||
/// as Discord sees it, though it defaults to their nickname at time of joining. It does not have to be unique, and |
||||
/// can be changed at any time. |
||||
name String |
||||
/// The discord user associated with this account. |
||||
discordUser DiscordUser? |
||||
/// The user's gender, for the purposes of the game. This is purely cosmetic and can be changed at any time. |
||||
gender Gender @relation(fields: [genderId], references: [id]) |
||||
/// Relation field for Gender |
||||
genderId String |
||||
/// The number of units of currency this user is currently carrying. |
||||
currency Int @default(100) |
||||
/// The time and date at which this user joined. |
||||
joinedAt DateTime @default(now()) |
||||
/// The last time this user used a command. |
||||
lastActive DateTime @default(now()) |
||||
/// The last time this user retrieved their daily resources. |
||||
lastDaily DateTime? |
||||
/// List of units this user has ever seen/pulled. |
||||
units UserUnit[] |
||||
/// List of units currently in this user's party. |
||||
summonedUnits SummonedUnit[] |
||||
} |
||||
|
||||
/// Informmation about a Discord user. |
||||
model DiscordUser { |
||||
/// The Discord ID this record is for. A Discord snowflake. |
||||
discordId String @id |
||||
/// The last known username associated with this user. |
||||
username String |
||||
/// The last known discriminator associated with this user. |
||||
discriminator String |
||||
/// The User that this DiscordUser is associated with. |
||||
user User? @relation(fields: [userId], references: [id]) |
||||
/// Relation field for User |
||||
userId String? @unique |
||||
} |
||||
|
||||
/// Definitions of unit tiers. |
||||
model Tier { |
||||
/// The internal ID associated with this tier. |
||||
id String @id @default(cuid()) |
||||
/// The human-readable name of this tier. Unique among tiers. |
||||
name String @unique |
||||
/// The chance of pulling a unit of this tier. |
||||
pullWeight Int |
||||
/// The cost of /recalling a unit of this tier. |
||||
recallCost Int |
||||
/// The list of units with this tier. |
||||
units Unit[] |
||||
} |
||||
|
||||
/// An individual unit that can be summoned. |
||||
model Unit { |
||||
/// The combination of Name and Subtitle is unique among units, allowing for multiple versions of a unit. |
||||
/// The internal ID associated with this unit. |
||||
id String @id @default(cuid()) |
||||
/// The name of this unit. |
||||
name String |
||||
/// The subtitle of this unit. |
||||
subtitle String |
||||
/// The description of this unit. |
||||
description String |
||||
/// The tier of this unit. |
||||
tier Tier @relation(fields: [tierId], references: [id]) |
||||
/// Relation field for Tier |
||||
tierId String |
||||
/// The unit's base health when summoned for the first time. |
||||
baseHealth Int |
||||
/// The unit's base strength when summoned for the first time. |
||||
baseStrength Int |
||||
/// Information about the bonds with users this unit has been summoned by. |
||||
users UserUnit[] |
||||
/// Information about this unit's summoned forms. |
||||
summonedUnits SummonedUnit[] |
||||
|
||||
@@unique([name, subtitle]) |
||||
} |
||||
|
||||
/// Connection between Users and Units, indicating how and when users have pulled this unit. |
||||
model UserUnit { |
||||
/// The User that summoned this unit at some point. |
||||
user User @relation(fields: [userId], references: [id]) |
||||
/// Relation field for User |
||||
userId String |
||||
/// The Unit that was summoned by this User at some point. |
||||
unit Unit @relation(fields: [unitId], references: [id]) |
||||
/// Relation field for Unit |
||||
unitId String |
||||
/// The first time this user pulled this unit. |
||||
firstPulled DateTime @default(now()) |
||||
/// The number of times this unit has been /pulled by this user. |
||||
/// Greatly increases the user's bond with this unit. |
||||
/// Higher bond means higher stats on being resummoned with /pull or /recall. |
||||
timesPulled Int @default(1) |
||||
/// The number of times this unit has been digested in this user's party, either with /feed or in battle. |
||||
/// Slightly decreases the user's bond with this unit. |
||||
/// If the total bond reaches zero, this unit can no longer be resummoned with /recall until they appear in /pull. |
||||
timesDigested Int @default(0) |
||||
/// The number of times this unit has digested other units, either with /feed or in battle. |
||||
/// Does not influence bond, but may have an influence on other things (e.g., Talk lines). |
||||
timesDigesting Int @default(0) |
||||
/// The summoned form of this unit, if this unit is currently summoned. |
||||
/// Created on pulling or recalling, destroyed on digestion. |
||||
summonedUnit SummonedUnit? |
||||
|
||||
@@id([userId, unitId]) |
||||
} |
||||
|
||||
/// Instances of summoned units. |
||||
model SummonedUnit { |
||||
/// The User this unit was summoned by. |
||||
user User @relation(fields: [userId], references: [id]) |
||||
/// The Unit this summoned unit is an instance of. |
||||
unit Unit @relation(fields: [unitId], references: [id]) |
||||
/// The user-unit pair this SummonedUnit originates with. |
||||
userUnit UserUnit @relation(fields: [userId, unitId], references: [userId, unitId]) |
||||
/// Relation field for User and UserUnit |
||||
userId String |
||||
/// Relation field for Unit and UserUnit |
||||
unitId String |
||||
/// The unit's current health. If 0, the unit is unconscious and cannot participate in fights. |
||||
/// At -MaxHealth, the unit has been fully digested and this record will be deleted. |
||||
currentHealth Int |
||||
/// The unit's maximum health. |
||||
maxHealth Int |
||||
/// The unit's strength. |
||||
strength Int |
||||
|
||||
@@id([userId, unitId]) |
||||
} |
@ -0,0 +1,46 @@ |
||||
import {CommandContext, SlashCommand, SlashCreator} from "slash-create"; |
||||
import {Snowflake} from "discord-api-types"; |
||||
import {Pool} from "pg"; |
||||
import {singleQueryResult} from "../../queries/QueryHelpers.js"; |
||||
import {sendErrorMessage} from "../../queries/ErrorCodes.js"; |
||||
|
||||
export class UnjoinCommand extends SlashCommand { |
||||
readonly pool: Pool |
||||
|
||||
constructor(creator: SlashCreator, {pool, gameGuildIds}: { |
||||
pool: Pool, |
||||
gameGuildIds: Snowflake[], |
||||
}) { |
||||
super(creator, { |
||||
name: "debug_unjoin", |
||||
guildIDs: gameGuildIds, |
||||
description: "Allows an existing player to quit the game.", |
||||
options: [] |
||||
}); |
||||
|
||||
this.pool = pool |
||||
} |
||||
|
||||
async run(ctx: CommandContext): Promise<void> { |
||||
try { |
||||
const result: number | undefined = singleQueryResult(await this.pool.query({ |
||||
text: "SELECT Command_Unjoin($1, $2, $3, $4, $5)", |
||||
values: [ctx.channelID, ctx.guildID, ctx.user.id, ctx.user.username, ctx.user.discriminator], |
||||
rowMode: "array", |
||||
})) |
||||
if (typeof result === "number") { |
||||
await ctx.send({ |
||||
content: `You got it! I've removed you from the register. Make sure to note down your old user ID: ${result}.`, |
||||
ephemeral: true, |
||||
}) |
||||
} else { |
||||
await ctx.send({ |
||||
content: `You're actually not on the register to begin with. So... mission accomplished?`, |
||||
ephemeral: true, |
||||
}) |
||||
} |
||||
} catch (e) { |
||||
await sendErrorMessage(ctx, e) |
||||
} |
||||
} |
||||
} |
@ -1,26 +0,0 @@ |
||||
import {CommandContext} from "slash-create"; |
||||
import {ChannelManager} from "../../queries/ChannelManager.js"; |
||||
|
||||
export async function checkGameCommandAndRun(ctx: CommandContext, channelManager: ChannelManager, handler: (ctx: CommandContext) => Promise<any>): Promise<any> { |
||||
const guildID = ctx.guildID |
||||
try { |
||||
if (await channelManager.canUseGameCommandsInChannel(ctx.channelID)) { |
||||
return handler(ctx) |
||||
} else if (guildID !== undefined && await channelManager.canUseGameCommandsInGuild(guildID)) { |
||||
return ctx.send({ |
||||
content: `Sorry, you can't do that in this channel.`, |
||||
ephemeral: true, |
||||
}) |
||||
} else { |
||||
return ctx.send({ |
||||
content: "Sorry, you can't do that in this guild.", |
||||
ephemeral: true, |
||||
}) |
||||
} |
||||
} catch (e) { |
||||
return ctx.send({ |
||||
content: `Uhhhhhh. Something went very wrong. If you see Reya, tell her I said ${e}.`, |
||||
ephemeral: true, |
||||
}) |
||||
} |
||||
} |
@ -1,95 +0,0 @@ |
||||
import {Snowflake} from "discord-api-types"; |
||||
import {PrismaClient} from "./Prisma.js"; |
||||
|
||||
export class ChannelManager { |
||||
readonly client: PrismaClient |
||||
|
||||
constructor(client: PrismaClient) { |
||||
this.client = client |
||||
} |
||||
|
||||
async getGameCommandGuildIds(): Promise<Snowflake[]> { |
||||
return (await this.client.discordChannel.findMany({ |
||||
where: { |
||||
acceptGameCommands: true, |
||||
guildId: { |
||||
not: null |
||||
} |
||||
}, |
||||
distinct: ["guildId"], |
||||
select: { |
||||
guildId: true, |
||||
}, |
||||
})).map((item) => item.guildId as string) |
||||
// We know that the guild ID is not null because of the where condition.
|
||||
} |
||||
|
||||
async canUseGameCommandsInChannel(channelId: Snowflake): Promise<boolean> { |
||||
return ((await this.client.discordChannel.findUnique({ |
||||
where: { |
||||
discordId: channelId, |
||||
}, |
||||
select: { |
||||
acceptGameCommands: true, |
||||
}, |
||||
rejectOnNotFound: false, |
||||
})) ?? {acceptGameCommands: false}).acceptGameCommands |
||||
} |
||||
|
||||
async canUseGameCommandsInGuild(guildId: Snowflake): Promise<boolean> { |
||||
return (await this.client.discordChannel.findFirst({ |
||||
where: { |
||||
guildId: guildId, |
||||
acceptGameCommands: true, |
||||
}, |
||||
select: { |
||||
discordId: true |
||||
} |
||||
})) !== null |
||||
} |
||||
|
||||
async getAdminCommandGuildIds(): Promise<Snowflake[]> { |
||||
return (await this.client.discordChannel.findMany({ |
||||
where: { |
||||
acceptAdminCommands: true, |
||||
guildId: { |
||||
not: null |
||||
} |
||||
}, |
||||
distinct: ["guildId"], |
||||
select: { |
||||
guildId: true, |
||||
}, |
||||
})).map((item) => item.guildId as string) |
||||
// We know that the guild ID is not null because of the where condition.
|
||||
} |
||||
|
||||
async canUseAdminCommandsInChannel(channelId: Snowflake): Promise<boolean> { |
||||
return ((await this.client.discordChannel.findUnique({ |
||||
where: { |
||||
discordId: channelId, |
||||
}, |
||||
select: { |
||||
acceptAdminCommands: true, |
||||
}, |
||||
rejectOnNotFound: false, |
||||
})) ?? {acceptAdminCommands: false} |
||||
).acceptAdminCommands |
||||
} |
||||
|
||||
async canUseAdminCommandsInGuild(guildId: Snowflake): Promise<boolean> { |
||||
return (await this.client.discordChannel.findFirst({ |
||||
where: { |
||||
guildId: guildId, |
||||
acceptAdminCommands: true, |
||||
}, |
||||
select: { |
||||
discordId: true, |
||||
} |
||||
})) !== null |
||||
} |
||||
|
||||
async isGameReady() { |
||||
return false; |
||||
} |
||||
} |
@ -0,0 +1,48 @@ |
||||
import {CommandContext} from "slash-create"; |
||||
import {DatabaseError} from "pg"; |
||||
|
||||
export enum ErrorCodes { |
||||
BAD_CHANNEL_ADMIN = "VGBCA", |
||||
BAD_CHANNEL_GAME = "VGBCG", |
||||
BAD_GUILD_ADMIN = "VGBGA", |
||||
BAD_GUILD_GAME = "VGBGG", |
||||
NOT_YET_JOINED = "VGNYJ", |
||||
NOT_ENOUGH_CURRENCY = "VGNEC", |
||||
} |
||||
|
||||
/** Checks if the error is a database error. */ |
||||
export function isPostgresError(err: unknown): err is DatabaseError { |
||||
return err instanceof DatabaseError |
||||
} |
||||
|
||||
/** Sends a message detailing the given error on the given command context. */ |
||||
export async function sendErrorMessage(ctx: CommandContext, err: unknown): Promise<void> { |
||||
console.log(err) |
||||
if (isPostgresError(err)) { |
||||
switch (err.code) { |
||||
case ErrorCodes.BAD_CHANNEL_ADMIN: |
||||
case ErrorCodes.BAD_CHANNEL_GAME: |
||||
case ErrorCodes.BAD_GUILD_ADMIN: |
||||
case ErrorCodes.BAD_GUILD_GAME: |
||||
case ErrorCodes.NOT_YET_JOINED: |
||||
case ErrorCodes.NOT_ENOUGH_CURRENCY: |
||||
await ctx.send({ |
||||
content: `**${err.message}**\n${err.detail}\n\n**Tip**: ${err.hint}`, |
||||
ephemeral: true, |
||||
}) |
||||
return |
||||
default: |
||||
await ctx.send({ |
||||
content: `**Unexpected Error (${err.code})**: ${err.message}\n${err.detail}\n\n**Tip**: ${err.hint}`, |
||||
ephemeral: true, |
||||
}) |
||||
return |
||||
} |
||||
} else { |
||||
await ctx.send({ |
||||
content: `**Unknown Error**: ${err}`, |
||||
ephemeral: true, |
||||
}) |
||||
return |
||||
} |
||||
} |
@ -1,9 +0,0 @@ |
||||
import pkg from "@prisma/client"; |
||||
|
||||
export const { |
||||
PrismaClient, |
||||
Prisma: PrismaNS, |
||||
prisma |
||||
} = pkg |
||||
export type PrismaClient = InstanceType<typeof PrismaClient>; |
||||
export type {Prisma, DiscordUser, User, DiscordChannel} from "@prisma/client"; |
@ -0,0 +1,13 @@ |
||||
import {QueryResult} from "pg"; |
||||
|
||||
export function singleQueryResult<T>(result: QueryResult<[T]>): T | undefined { |
||||
return singleColumnQueryResult(result)[0] |
||||
} |
||||
|
||||
export function singleColumnQueryResult<T>(result: QueryResult<[T]>): T[] { |
||||
return result.rows.map(([item]) => item) |
||||
} |
||||
|
||||
export function singleRowQueryResult<T>(result: QueryResult<T>): T | undefined { |
||||
return result.rows[0] |
||||
} |
@ -1,133 +0,0 @@ |
||||
import {DiscordUser, Prisma, PrismaClient} from "./Prisma.js"; |
||||
import {Snowflake} from "discord-api-types"; |
||||
import cuid from "cuid"; |
||||
|
||||
const userRegistrationSelect = { |
||||
id: true, |
||||
name: true, |
||||
discordUser: true, |
||||
gender: true, |
||||
joinedAt: true, |
||||
} as const |
||||
export type UserRegistrationData = Prisma.UserGetPayload<{ select: typeof userRegistrationSelect }> |
||||
|
||||
const genderListSelect = { |
||||
id: true, |
||||
name: true, |
||||
} as const |
||||
export type GenderListData = Prisma.GenderGetPayload<{ select: typeof genderListSelect }> |
||||
|
||||
export class UserManager { |
||||
readonly client: PrismaClient |
||||
|
||||
constructor(client: PrismaClient) { |
||||
this.client = client |
||||
} |
||||
|
||||
async registerOrUpdateDiscordUser({ |
||||
discordId, |
||||
username, |
||||
discriminator, |
||||
}: { discordId: Snowflake, username: string, discriminator: string }): Promise<DiscordUser> { |
||||
return (await this.client.discordUser.upsert({ |
||||
where: { |
||||
discordId, |
||||
}, |
||||
create: { |
||||
discordId, |
||||
username, |
||||
discriminator, |
||||
userId: null, |
||||
}, |
||||
update: { |
||||
username, |
||||
discriminator, |
||||
user: { |
||||
update: { |
||||
lastActive: new Date() |
||||
} |
||||
} |
||||
}, |
||||
include: { |
||||
user: true, |
||||
} |
||||
})) |
||||
} |
||||
|
||||
async registerOrReregisterUserFromDiscord({ |
||||
discordId, |
||||
username, |
||||
discriminator, |
||||
name, |
||||
genderId |
||||
}: { discordId: Snowflake, username: string, discriminator: string, name: string, genderId: string }): Promise<{ |
||||
user: UserRegistrationData, created: boolean |
||||
}> { |
||||
const userId = cuid() |
||||
const user = (await this.client.discordUser.upsert({ |
||||
where: { |
||||
discordId, |
||||
}, |
||||
update: { |
||||
username, |
||||
discriminator, |
||||
user: { |
||||
upsert: { |
||||
update: { |
||||
name, |
||||
gender: { |
||||
connect: { |
||||
id: genderId, |
||||
} |
||||
}, |
||||
lastActive: new Date() |
||||
}, |
||||
create: { |
||||
id: userId, |
||||
name, |
||||
gender: { |
||||
connect: { |
||||
id: genderId, |
||||
} |
||||
}, |
||||
} |
||||
} |
||||
} |
||||
}, |
||||
create: { |
||||
discordId, |
||||
username, |
||||
discriminator, |
||||
user: { |
||||
create: { |
||||
id: userId, |
||||
name, |
||||
gender: { |
||||
connect: { |
||||
id: genderId, |
||||
} |
||||
}, |
||||
} |
||||
} |
||||
}, |
||||
select: { |
||||
user: { |
||||
select: userRegistrationSelect |
||||
} |
||||
}, |
||||
})).user |
||||
if (user === null) { |
||||
throw Error("...Somehow, there wasn't a user to return?!") |
||||
} |
||||
return { |
||||
user, |
||||
created: user.id === userId, |
||||
} |
||||
} |
||||
|
||||
async getGenders(): Promise<GenderListData[]> { |
||||
return this.client.gender.findMany({ |
||||
select: genderListSelect |
||||
}) |
||||
} |
||||
} |
@ -1,44 +0,0 @@ |
||||
import {PrismaClient} from "../queries/Prisma.js"; |
||||
|
||||
async function main() { |
||||
const client = new PrismaClient() |
||||
await client.$connect() |
||||
await client.gender.upsert({ |
||||
where: { |
||||
id: "f" |
||||
}, |
||||
create: { |
||||
id: "f", |
||||
name: "Female" |
||||
}, |
||||
update: { |
||||
name: "Female" |
||||
}, |
||||
}) |
||||
await client.gender.upsert({ |
||||
where: { |
||||
id: "m" |
||||
}, |
||||
create: { |
||||
id: "m", |
||||
name: "Male" |
||||
}, |
||||
update: { |
||||
name: "Male" |
||||
}, |
||||
}) |
||||
await client.gender.upsert({ |
||||
where: { |
||||
id: "x" |
||||
}, |
||||
create: { |
||||
id: "x", |
||||
name: "Non-binary" |
||||
}, |
||||
update: { |
||||
name: "Non-binary" |
||||
}, |
||||
}) |
||||
} |
||||
|
||||
main() |
@ -1,54 +1,30 @@ |
||||
import {Prisma, PrismaClient} from "../queries/Prisma.js"; |
||||
import {APIWebhook} from "discord-api-types"; |
||||
import {readFile} from "fs/promises"; |
||||
import {Pool} from "pg"; |
||||
import dotenv from "dotenv"; |
||||
|
||||
type DiscordChannelPermissions = Prisma.DiscordChannelGetPayload<{ |
||||
select: { |
||||
broadcastGame: true, |
||||
sendLogs: true, |
||||
acceptGameCommands: true, |
||||
acceptAdminCommands: true, |
||||
} |
||||
}> |
||||
|
||||
async function loadHookIntoDatabase(client: PrismaClient, hook: APIWebhook, permissions: DiscordChannelPermissions): Promise<void> { |
||||
await client.discordChannel.upsert({ |
||||
where: {discordId: hook.channel_id}, |
||||
update: { |
||||
webhookId: hook.id, |
||||
token: hook.token, |
||||
...permissions |
||||
}, |
||||
create: { |
||||
discordId: hook.channel_id, |
||||
guildId: hook.guild_id ?? null, |
||||
webhookId: hook.id, |
||||
token: hook.token, |
||||
name: "???", |
||||
priority: 0, |
||||
...permissions |
||||
} |
||||
async function loadHooksIntoDatabase(client: Pool, gameHook: APIWebhook & { channelName: string }, adminHook: APIWebhook & { channelName: string }): Promise<void> { |
||||
await client.query({ |
||||
text: ` |
||||
INSERT INTO DiscordChannel (discordId, name, broadcastGame, sendLogs, acceptGameCommands, |
||||
acceptAdminCommands, priority, guildId, webhookId, webhookToken) |
||||
VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10), |
||||
($11, $12, $13, $14, $15, $16, $17, $18, $19, $20) |
||||
ON CONFLICT DO NOTHING`,
|
||||
values: [gameHook.channel_id, gameHook.channelName, true, false, true, false, 0, gameHook.guild_id, gameHook.id, gameHook.token, |
||||
adminHook.channel_id, adminHook.channelName, false, true, false, true, 0, adminHook.guild_id, adminHook.id, adminHook.token] |
||||
}) |
||||
} |
||||
|
||||
async function main() { |
||||
const client = new PrismaClient() |
||||
await client.$connect() |
||||
|
||||
const gameHook: APIWebhook = JSON.parse(await readFile("runtime/webhooks/game.json", {encoding: "utf-8"})) |
||||
await loadHookIntoDatabase(client, gameHook, { |
||||
acceptAdminCommands: false, |
||||
acceptGameCommands: true, |
||||
sendLogs: false, |
||||
broadcastGame: true, |
||||
}) |
||||
const adminHook: APIWebhook = JSON.parse(await readFile("runtime/webhooks/admin.json", {encoding: "utf-8"})) |
||||
await loadHookIntoDatabase(client, adminHook, { |
||||
acceptAdminCommands: true, |
||||
acceptGameCommands: false, |
||||
sendLogs: true, |
||||
broadcastGame: false, |
||||
const {DATABASE_URL: connectionString} = dotenv.config().parsed ?? {} |
||||
const client = new Pool({ |
||||
connectionString |
||||
}) |
||||
|
||||
const gameHook: APIWebhook & { channelName: string } = JSON.parse(await readFile("runtime/webhooks/game.json", {encoding: "utf-8"})) |
||||
const adminHook: APIWebhook & { channelName: string } = JSON.parse(await readFile("runtime/webhooks/admin.json", {encoding: "utf-8"})) |
||||
await loadHooksIntoDatabase(client, gameHook, adminHook) |
||||
} |
||||
|
||||
main() |
Loading…
Reference in new issue