Gacha game centered around vore.
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 
vore-gacha/migrations/committed/000008-all-the-procedures.sql

367 lines
15 KiB

--! 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';