PostgreSGL 10 Standards (#1127)

* attempting to resolve pg14->pg10 issues

* unidon't

* rev 1

* rev 2

* rev 3

* rev 4
This commit is contained in:
Fate-JH 2023-10-08 11:52:50 -04:00 committed by GitHub
parent c68d5e9864
commit 0b0b23d99c
No known key found for this signature in database
GPG key ID: 4AEE18F83AFDEB23
4 changed files with 441 additions and 110 deletions

View file

@ -134,7 +134,7 @@ lazy val QuietTest = config("quiet") extend Test
lazy val docs = (project in file("docs")) lazy val docs = (project in file("docs"))
.settings(psforeverSettings: _*) .settings(psforeverSettings: _*)
.enablePlugins(ScalaUnidocPlugin) //.enablePlugins(ScalaUnidocPlugin)
.settings( .settings(
name := "psforever" name := "psforever"
) )

View file

@ -3,6 +3,6 @@ logLevel := Level.Warn
addSbtPlugin("org.xerial.sbt" % "sbt-pack" % "0.17") addSbtPlugin("org.xerial.sbt" % "sbt-pack" % "0.17")
addSbtPlugin("org.scoverage" % "sbt-scoverage" % "2.0.7") addSbtPlugin("org.scoverage" % "sbt-scoverage" % "2.0.7")
addSbtPlugin("io.kamon" % "sbt-kanela-runner" % "2.0.14") addSbtPlugin("io.kamon" % "sbt-kanela-runner" % "2.0.14")
addSbtPlugin("com.eed3si9n" % "sbt-unidoc" % "0.4.3") //addSbtPlugin("com.eed3si9n" % "sbt-unidoc" % "0.4.3")
addSbtPlugin("org.scalameta" % "sbt-scalafmt" % "2.5.0") addSbtPlugin("org.scalameta" % "sbt-scalafmt" % "2.5.0")
addSbtPlugin("ch.epfl.scala" % "sbt-scalafix" % "0.10.4") addSbtPlugin("ch.epfl.scala" % "sbt-scalafix" % "0.10.4")

View file

@ -17,9 +17,10 @@ CREATE TABLE IF NOT EXISTS "sessionnumber" (
CREATE TABLE IF NOT EXISTS "killactivity" ( CREATE TABLE IF NOT EXISTS "killactivity" (
"index" SERIAL PRIMARY KEY NOT NULL, "index" SERIAL PRIMARY KEY NOT NULL,
"victim_id" INT NOT NULL REFERENCES avatar (id),
"killer_id" INT NOT NULL REFERENCES avatar (id), "killer_id" INT NOT NULL REFERENCES avatar (id),
"victim_id" INT NOT NULL REFERENCES avatar (id),
"victim_exosuit" SMALLINT NOT NULL, "victim_exosuit" SMALLINT NOT NULL,
"victim_mounted" INT NOT NULL DEFAULT 0,
"weapon_id" SMALLINT NOT NULL, "weapon_id" SMALLINT NOT NULL,
"zone_id" SMALLINT NOT NULL, "zone_id" SMALLINT NOT NULL,
"px" INT NOT NULL, "px" INT NOT NULL,
@ -30,10 +31,10 @@ CREATE TABLE IF NOT EXISTS "killactivity" (
); );
CREATE TABLE IF NOT EXISTS "kda" ( CREATE TABLE IF NOT EXISTS "kda" (
"avatar_id" INT NOT NULL REFERENCES avatar (id), "avatar_id" INT NOT NULL REFERENCES avatar (id),
"kills" INT NOT NULL DEFAULT 0, "kills" INT NOT NULL DEFAULT 0,
"deaths" INT NOT NULL DEFAULT 0, "deaths" INT NOT NULL DEFAULT 0,
"assists" INT NOT NULL DEFAULT 0, "revives" INT NOT NULL DEFAULT 0,
UNIQUE(avatar_id) UNIQUE(avatar_id)
); );
@ -42,12 +43,12 @@ CREATE TABLE IF NOT EXISTS "kdasession" (
"session_id" INT NOT NULL, "session_id" INT NOT NULL,
"kills" INT NOT NULL DEFAULT 0, "kills" INT NOT NULL DEFAULT 0,
"deaths" INT NOT NULL DEFAULT 0, "deaths" INT NOT NULL DEFAULT 0,
"assists" INT NOT NULL DEFAULT 0, "revives" INT NOT NULL DEFAULT 0,
UNIQUE(avatar_id, session_id) UNIQUE(avatar_id, session_id)
); );
CREATE TABLE IF NOT EXISTS "weaponstat" ( CREATE TABLE IF NOT EXISTS "weaponstat" (
"avatar_id" INT NOT NULL REFERENCES avatar (id), "avatar_id" INT NOT NULL REFERENCES avatar (id),
"weapon_id" SMALLINT NOT NULL, "weapon_id" SMALLINT NOT NULL,
"shots_fired" INT NOT NULL DEFAULT 0, "shots_fired" INT NOT NULL DEFAULT 0,
"shots_landed" INT NOT NULL DEFAULT 0, "shots_landed" INT NOT NULL DEFAULT 0,
@ -73,89 +74,144 @@ CREATE TABLE IF NOT EXISTS "legacykills" (
UNIQUE(avatar_id) UNIQUE(avatar_id)
); );
CREATE VIEW kdacampaign AS ( CREATE TABLE IF NOT EXISTS "machinedestroyed" (
SELECT "index" SERIAL PRIMARY KEY NOT NULL,
session.avatar_id, "avatar_id" INT NOT NULL REFERENCES avatar (id),
SUM(session.kills) AS kills, "weapon_id" INT NOT NULL,
SUM(session.deaths) AS deaths, "machine_type" INT NOT NULL,
SUM(session.assists) AS assists, "machine_faction" SMALLINT NOT NULL,
COUNT(session.avatar_id) AS numberOfSessions "hacked_faction" SMALLINT NOT NULL,
FROM ( "as_cargo" BOOLEAN NOT NULL,
SELECT avatar_id, session_id, kills, deaths, assists "zone_num" SMALLINT NOT NULL,
FROM kdasession "px" INT NOT NULL,
UNION ALL "py" INT NOT NULL,
SELECT avatar_id, 0, kills, deaths, assists "pz" INT NOT NULL,
FROM kda "timestamp" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
) AS session
LEFT JOIN kda
ON kda.avatar_id = session.avatar_id
GROUP BY session.avatar_id
); );
CREATE VIEW weaponstatcampaign AS ( CREATE TABLE IF NOT EXISTS "assistactivity" (
SELECT "index" SERIAL PRIMARY KEY NOT NULL,
weaponstat.avatar_id, "victim_id" INT NOT NULL REFERENCES avatar (id),
weaponstat.weapon_id, "attacker_id" INT NOT NULL REFERENCES avatar (id),
SUM(session.shots_fired) AS shots_fired, "weapon_id" SMALLINT NOT NULL,
SUM(session.shots_landed) AS shots_landed, "zone_id" SMALLINT NOT NULL,
SUM(session.kills) AS kills, "px" INT NOT NULL,
SUM(session.assists) AS assists, "py" INT NOT NULL,
COUNT(session.session_id) AS numberOfSessions "pz" INT NOT NULL,
FROM ( "exp" INT NOT NULL,
SELECT avatar_id, weapon_id, session_id, shots_fired, shots_landed, kills, assists "timestamp" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
FROM weaponstatsession
UNION ALL
SELECT avatar_id, weapon_id, 0, shots_fired, shots_landed, kills, assists
FROM weaponstat
) AS session
LEFT JOIN weaponstat
ON weaponstat.avatar_id = session.avatar_id
GROUP BY weaponstat.avatar_id, weaponstat.weapon_id
); );
/* CREATE TABLE IF NOT EXISTS "supportactivity" (
Procedure for initializing and increasing the session number. "index" SERIAL PRIMARY KEY NOT NULL,
Always indexes a new session. "user_id" INT NOT NULL REFERENCES avatar (id), -- player that provides the support
*/ "target_id" INT NOT NULL REFERENCES avatar (id), -- benefactor of the support
CREATE OR REPLACE PROCEDURE proc_sessionnumber_initAndOrIncrease "target_exosuit" SMALLINT NOT NULL, -- benefactor's exo-suit
(avatarId IN Int, number OUT Int) "interaction_type" SMALLINT NOT NULL, -- classification of support
AS "intermediate_type" INT DEFAULT 0, -- through what medium user_id supports target_id
$$ "implement_type" INT DEFAULT 0, -- tool utilized by user_id to support target_id, potentially via interaction with intermediate_type
BEGIN "exp" INT NOT NULL,
SELECT (MAX(session_id,0)+1) INTO number "timestamp" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
FROM sessionnumber );
WHERE avatar_id = avatarId;
INSERT INTO sessionnumber CREATE TABLE IF NOT EXISTS "ntuactivity" (
VALUES (avatarId, number); "avatar_id" INT NOT NULL REFERENCES avatar (id),
END; "zone_id" INT NOT NULL,
$$ LANGUAGE plpgsql; "building_id" INT NOT NULL,
"exp" INT NOT NULL,
UNIQUE(avatar_id, zone_id, building_id)
);
CREATE TABLE IF NOT EXISTS "buildingcapture" (
"index" SERIAL PRIMARY KEY NOT NULL,
"avatar_id" INT NOT NULL REFERENCES avatar (id),
"zone_id" INT NOT NULL,
"building_id" INT NOT NULL,
"exp" INT NOT NULL,
"exp_type" CHAR(3) NOT NULL, /* bep, cep, llu */
"timestamp" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE IF NOT EXISTS "expbuildingcapture" (
"avatar_id" INT NOT NULL REFERENCES avatar (id),
"zone_id" INT NOT NULL,
"building_id" INT NOT NULL,
"captures" INT NOT NULL,
"bep" INT NOT NULL,
"cep" INT NOT NULL,
UNIQUE(avatar_id, zone_id, building_id)
);
CREATE TABLE IF NOT EXISTS "llubuildingcapture" (
"avatar_id" INT NOT NULL REFERENCES avatar (id),
"zone_id" INT NOT NULL,
"building_id" INT NOT NULL,
"captures" INT NOT NULL,
"exp" INT NOT NULL,
UNIQUE(avatar_id, zone_id, building_id)
);
CREATE TABLE IF NOT EXISTS "progressiondebt" (
"avatar_id" INT NOT NULL REFERENCES avatar (id),
"experience" INT NOT NULL DEFAULT 0,
UNIQUE(avatar_id)
);
/* /*
Procedure for initializing and increasing the session number. Procedure for initializing and increasing the session number.
Index for a new session only if last session was created more than one hour ago. Index for a new session only if last session was created more than one hour ago.
*/ */
CREATE OR REPLACE PROCEDURE proc_sessionnumber_initAndOrIncreasePerHour CREATE OR REPLACE FUNCTION proc_sessionnumber_test
(avatarId IN Int, number OUT Int, nextNumber OUT Int) (avatarId integer)
RETURNS integer
AS AS
$$ $$
DECLARE time TIMESTAMP; DECLARE time TIMESTAMP;
DECLARE number integer;
BEGIN BEGIN
SELECT MAX(session_id,0) INTO number SELECT MAX(session_id) INTO number
FROM sessionnumber FROM sessionnumber
WHERE avatar_id = avatarId; WHERE avatar_id = avatarId;
SELECT timestamp INTO time SELECT COALESCE(timestamp) INTO time
FROM sessionnumber FROM sessionnumber
WHERE avatar_id = avatarId AND session_id = number; WHERE avatar_id = avatarId AND session_id = number;
IF (CAST(CURRENT_TIMESTAMP AS FLOAT) > CAST(DATE_ADD('hour', 1, DATE_TRUNC('hour', time)) AS FLOAT)) THEN IF (time IS null) THEN
number := 0;
END IF;
RETURN number;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION proc_sessionnumber_initAndOrIncreasePerHour
(avatarId integer)
RETURNS integer
AS
$$
DECLARE time TIMESTAMP;
DECLARE number integer;
DECLARE nextNumber integer;
BEGIN
SELECT MAX(session_id) INTO number
FROM sessionnumber
WHERE avatar_id = avatarId;
SELECT COALESCE(timestamp) INTO time
FROM sessionnumber
WHERE avatar_id = avatarId AND session_id = number;
IF (time IS null) THEN
nextNumber := 1;
INSERT INTO sessionnumber
VALUES (avatarId, nextNumber);
ELSIF (CURRENT_TIMESTAMP > DATE_TRUNC('hour', time) + interval '1' hour) THEN
nextNumber := number + 1; nextNumber := number + 1;
INSERT INTO sessionnumber INSERT INTO sessionnumber
VALUES (avatarId, number); VALUES (avatarId, nextNumber);
ELSE ELSE
nextNumber := number; nextNumber := number;
UPDATE sessionnumber UPDATE sessionnumber
SET timestamp = CURRENT_TIMESTAMP SET timestamp = CURRENT_TIMESTAMP
WHERE avatar_id = avatarId AND session_id = number; WHERE avatar_id = avatarId AND session_id = number;
END IF; END IF;
RETURN nextNumber;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
@ -163,24 +219,35 @@ $$ LANGUAGE plpgsql;
Procedure for accessing any existing session number. Procedure for accessing any existing session number.
Actually polls the previous session number from the account table. Actually polls the previous session number from the account table.
*/ */
CREATE OR REPLACE PROCEDURE proc_sessionnumber_get CREATE OR REPLACE FUNCTION proc_sessionnumber_get
(avatarId IN Int, number OUT Int) (avatarId integer)
RETURNS integer
AS AS
$$ $$
DECLARE sessionId integer;
DECLARE number integer;
BEGIN BEGIN
SELECT COALESCE(session_id,0) INTO number SELECT COALESCE(session_id) INTO sessionId
FROM account FROM account
WHERE avatar_logged_in = avatarId; WHERE avatar_logged_in = avatarId;
IF sessionId IS NULL THEN
number := 0;
ELSE
number := sessionId;
END IF;
RETURN number;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
/* /*
Procedures for ensuring that row entries can be found in specified tables before some other DML operation updates those row entries. Procedures for ensuring that row entries can be found in specified tables before some other DML operation updates those row entries.
*/ */
CREATE OR REPLACE PROCEDURE proc_kda_addEntryIfNone CREATE OR REPLACE FUNCTION proc_kda_addEntryIfNone
(avatarId IN Int) (avatarId integer)
RETURNS integer
AS AS
$$ $$
DECLARE out integer;
BEGIN BEGIN
IF EXISTS( IF EXISTS(
SELECT * SELECT *
@ -189,43 +256,115 @@ BEGIN
HAVING COUNT(*) = 0) THEN HAVING COUNT(*) = 0) THEN
INSERT INTO kda (avatar_id) INSERT INTO kda (avatar_id)
VALUES (avatarId); VALUES (avatarId);
out := 1;
ELSE
out := 0;
END IF; END IF;
RETURN out;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE OR REPLACE PROCEDURE proc_weaponstat_addEntryIfNone CREATE OR REPLACE FUNCTION proc_weaponstat_addEntryIfNone
(avatarId IN Int, weaponId IN Int) (avatarId integer, weaponId integer)
RETURNS integer
AS AS
$$ $$
DECLARE sessionId Int; DECLARE out integer;
BEGIN BEGIN
SELECT proc_sessionnumber_get(avatarId, sessionId); IF NOT EXISTS(
IF EXISTS( SELECT avatar_id, weapon_id
SELECT *
FROM weaponstat FROM weaponstat
WHERE avatar_id = avatarId AND weapon_id = weaponId WHERE avatar_id = avatarId AND weapon_id = weaponId
HAVING COUNT(*) = 0) THEN GROUP BY avatar_id, weapon_id
INSERT INTO weaponstat (avatar_id, session_id, weapon_id) ) THEN
VALUES (avatarId, sessionId, weaponId); INSERT INTO weaponstat (avatar_id, weapon_id)
VALUES (avatarId, weaponId);
out := 1;
ELSE
out := 0;
END IF; END IF;
RETURN out;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE OR REPLACE PROCEDURE proc_weaponstatsession_addEntryIfNone CREATE OR REPLACE FUNCTION proc_weaponstatsession_addEntryIfNoneWithSessionId
(avatarId IN Int, weaponId IN Int) (avatarId integer, weaponId integer, sessionId integer)
RETURNS integer
AS
$$
DECLARE out integer;
BEGIN
IF NOT EXISTS(
SELECT avatar_id, session_id, weapon_id
FROM weaponstatsession
WHERE avatar_id = avatarId AND weapon_id = weaponId AND session_id = sessionId
GROUP BY avatar_id, session_id, weapon_id
) THEN
INSERT INTO weaponstatsession (avatar_id, session_id, weapon_id)
VALUES (avatarId, sessionId, weaponId);
out := 1;
ELSE
out := 0;
END IF;
RETURN out;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION proc_weaponstatsession_addEntryIfNone
(avatarId integer, weaponId integer)
RETURNS integer
AS AS
$$ $$
DECLARE sessionId Int; DECLARE sessionId Int;
BEGIN BEGIN
SELECT proc_sessionnumber_get(avatarId, sessionId); sessionId := proc_sessionnumber_get(avatarId);
IF EXISTS( RETURN proc_weaponstatsession_addEntryIfNoneWithSessionId(avatarId, weaponId, sessionId);
SELECT * END;
FROM weaponstatsession $$ LANGUAGE plpgsql;
WHERE avatar_id = avatarId AND weapon_id = weaponId
HAVING COUNT(*) = 0) THEN CREATE OR REPLACE FUNCTION proc_expbuildingcapture_addEntryIfNone
INSERT INTO weaponstatsession (avatar_id, session_id, weapon_id) (avatarId integer, buildingId integer, zoneId integer)
VALUES (avatarId, sessionId, weaponId); RETURNS integer
AS
$$
DECLARE out integer;
BEGIN
IF NOT EXISTS(
SELECT avatar_id, building_id, zone_id
FROM expbuildingcapture
WHERE avatar_id = avatarId AND building_id = buildingId AND zone_id = zoneId
GROUP BY avatar_id, building_id, zone_id
) THEN
INSERT INTO expbuildingcapture (avatar_id, building_id, zone_id, captures, bep, cep)
VALUES (avatarId, building_id, zone_id, 0, 0, 0);
out := 1;
ELSE
out := 0;
END IF; END IF;
RETURN out;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION proc_llubuildingcapture_addEntryIfNone
(avatarId integer, buildingId integer, zoneId integer)
RETURNS integer
AS
$$
DECLARE out integer;
BEGIN
IF NOT EXISTS(
SELECT avatar_id, building_id, zone_id
FROM llubuildingcapture
WHERE avatar_id = avatarId AND building_id = buildingId AND zone_id = zoneId
GROUP BY avatar_id, building_id, zone_id
) THEN
INSERT INTO llubuildingcapture (avatar_id, building_id, zone_id, captures, exp)
VALUES (avatarId, building_id, zone_id, 0, 0);
out := 1;
ELSE
out := 0;
END IF;
RETURN out;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
@ -243,11 +382,12 @@ DECLARE sessionId Int;
DECLARE oldSessionId Int; DECLARE oldSessionId Int;
BEGIN BEGIN
avatarId := NEW.avatar_logged_in; avatarId := NEW.avatar_logged_in;
SELECT proc_sessionnumber_initAndOrIncreasePerHour(avatarId, oldSessionId, sessionId); oldSessionId := proc_sessionnumber_test(avatarId);
sessionId := proc_sessionnumber_initAndOrIncreasePerHour(avatarId);
IF (sessionId > oldSessionId) THEN IF (sessionId > oldSessionId) THEN
BEGIN BEGIN
UPDATE account UPDATE account
SET sessionId = sessionId SET session_id = sessionId
WHERE id = OLD.id; WHERE id = OLD.id;
INSERT INTO kdasession (avatar_id, session_id) INSERT INTO kdasession (avatar_id, session_id)
VALUES (avatarId, sessionId); VALUES (avatarId, sessionId);
@ -257,8 +397,8 @@ BEGIN
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE OR REPLACE TRIGGER psf_account_newSession CREATE TRIGGER psf_account_newSession
BEFORE UPDATE AFTER UPDATE
OF avatar_logged_in OF avatar_logged_in
ON account ON account
FOR EACH ROW FOR EACH ROW
@ -281,12 +421,13 @@ DECLARE victimSessionId Int;
DECLARE killerId Int; DECLARE killerId Int;
DECLARE victimId Int; DECLARE victimId Int;
DECLARE weaponId Int; DECLARE weaponId Int;
DECLARE out integer;
BEGIN BEGIN
killerId := NEW.killer_id; killerId := NEW.killer_id;
victimId := NEW.victim_id; victimId := NEW.victim_id;
weaponId := NEW.weapon_id; weaponId := NEW.weapon_id;
SELECT proc_sessionnumber_get(killerId, killerSessionId); killerSessionId := proc_sessionnumber_get(killerId);
SELECT proc_sessionnumber_get(victimId, victimSessionId); victimSessionId := proc_sessionnumber_get(victimId);
BEGIN BEGIN
UPDATE kdasession UPDATE kdasession
SET kills = kills + 1 SET kills = kills + 1
@ -298,6 +439,7 @@ BEGIN
WHERE avatar_id = victimId AND session_id = victimSessionId; WHERE avatar_id = victimId AND session_id = victimSessionId;
END; END;
BEGIN BEGIN
out := proc_weaponstatsession_addEntryIfNoneWithSessionId(killerId, weaponId, killerSessionId);
UPDATE weaponstatsession UPDATE weaponstatsession
SET kills = kills + 1 SET kills = kills + 1
WHERE avatar_id = killerId AND session_id = killerSessionId AND weapon_id = weaponId; WHERE avatar_id = killerId AND session_id = killerSessionId AND weapon_id = weaponId;
@ -306,7 +448,7 @@ BEGIN
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE OR REPLACE TRIGGER psf_killactivity_updateRelatedStats CREATE TRIGGER psf_killactivity_updateRelatedStats
AFTER INSERT AFTER INSERT
ON killactivity ON killactivity
FOR EACH ROW FOR EACH ROW
@ -323,14 +465,16 @@ AS
$$ $$
DECLARE avatarId Int; DECLARE avatarId Int;
DECLARE weaponId Int; DECLARE weaponId Int;
DECLARE out integer;
BEGIN BEGIN
avatarId := NEW.avatar_id; avatarId := NEW.avatar_id;
weaponId := NEW.weapon_id; weaponId := NEW.weapon_id;
SELECT proc_weaponstatsession_addEntryIfNone(avatarId, weaponId); out := proc_weaponstatsession_addEntryIfNone(avatarId, weaponId);
RETURN NEW;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE OR REPLACE TRIGGER psf_weaponstatsession_addEntryIfNone CREATE TRIGGER psf_weaponstatsession_addEntryIfNone
BEFORE UPDATE BEFORE UPDATE
ON weaponstatsession ON weaponstatsession
FOR EACH ROW FOR EACH ROW
@ -346,13 +490,15 @@ RETURNS TRIGGER
AS AS
$$ $$
DECLARE avatarId Int; DECLARE avatarId Int;
DECLARE out integer;
BEGIN BEGIN
avatarId := NEW.avatar_id; avatarId := NEW.avatar_id;
SELECT proc_kda_addEntryIfNone(avatarId); out := proc_kda_addEntryIfNone(avatarId);
RETURN NEW;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE OR REPLACE TRIGGER psf_kda_addEntryIfNone CREATE TRIGGER psf_kda_addEntryIfNone
BEFORE UPDATE BEFORE UPDATE
ON kda ON kda
FOR EACH ROW FOR EACH ROW
@ -369,23 +515,55 @@ AS
$$ $$
DECLARE avatarId Int; DECLARE avatarId Int;
DECLARE weaponId Int; DECLARE weaponId Int;
DECLARE out integer;
BEGIN BEGIN
avatarId := NEW.avatar_id; avatarId := NEW.avatar_id;
weaponId := NEW.weapon_id; weaponId := NEW.weapon_id;
SELECT proc_weaponstat_addEntryIfNone(avatarId, weaponId); out := proc_weaponstat_addEntryIfNone(avatarId, weaponId);
RETURN NEW;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE OR REPLACE TRIGGER psf_weaponstat_addEntryIfNone CREATE TRIGGER psf_weaponstat_addEntryIfNone
BEFORE UPDATE BEFORE UPDATE
ON weaponstat ON weaponstat
FOR EACH ROW FOR EACH ROW
EXECUTE FUNCTION fn_weaponstat_addEntryIfNone(); EXECUTE FUNCTION fn_weaponstat_addEntryIfNone();
/*
Before attempting to update the revival data in a character's session kda column,
set the session id to the current value then
manually update the column, overriding the process.
*/
CREATE OR REPLACE FUNCTION fn_kdasession_updateRevives()
RETURNS TRIGGER
AS
$$
DECLARE avatarId Int;
DECLARE sessionId Int;
DECLARE newRevives Int;
BEGIN
avatarId := NEW.avatar_id;
sessionId := proc_sessionnumber_get(avatarId);
newRevives := NEW.revives;
if (newRevives > 0) THEN
UPDATE kdasession
SET revives = revives + newRevives
WHERE avatar_id = avatarId AND session_id = sessionId;
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER psf_kdasession_updateRevives
BEFORE INSERT
ON kdasession
FOR EACH ROW
EXECUTE FUNCTION fn_kdasession_updateRevives();
/* /*
Upon deletion of row entries for a character's session KDA, Upon deletion of row entries for a character's session KDA,
the values are copied over to the campaign KDA record for that character. the values are copied over to the campaign KDA record for that character.
This will fire mainly when called by the trigger for login (above).
*/ */
CREATE OR REPLACE FUNCTION fn_kdasession_updateOnDelete() CREATE OR REPLACE FUNCTION fn_kdasession_updateOnDelete()
RETURNS TRIGGER RETURNS TRIGGER
@ -394,22 +572,24 @@ $$
DECLARE avatarId Int; DECLARE avatarId Int;
DECLARE oldKills Int; DECLARE oldKills Int;
DECLARE oldDeaths Int; DECLARE oldDeaths Int;
DECLARE oldAssists Int; DECLARE oldRevives Int;
DECLARE out integer;
BEGIN BEGIN
avatarId := OLD.avatar_id; avatarId := OLD.avatar_id;
oldKills := OLD.kills; oldKills := OLD.kills;
oldDeaths := OLD.deaths; oldDeaths := OLD.deaths;
oldAssists := OLD.assists; oldRevives := OLD.Revives;
out := proc_kda_addEntryIfNone(avatarId);
UPDATE kda UPDATE kda
SET kills = kills + oldKills, SET kills = kills + oldKills,
deaths = deaths + oldDeaths, deaths = deaths + oldDeaths,
assists = assists + oldAssists revives = revives + oldRevives
WHERE avatar_id = avatarId; WHERE avatar_id = avatarId;
RETURN OLD; RETURN OLD;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE OR REPLACE TRIGGER psf_kdasession_updateOnDelete CREATE TRIGGER psf_kdasession_updateOnDelete
BEFORE DELETE BEFORE DELETE
ON kdasession ON kdasession
FOR EACH ROW FOR EACH ROW
@ -418,7 +598,6 @@ EXECUTE FUNCTION fn_kdasession_updateOnDelete();
/* /*
Upon deletion of row entries for a character's session weapon stats, Upon deletion of row entries for a character's session weapon stats,
the values are copied over to the campaign weapon stats record for that character. the values are copied over to the campaign weapon stats record for that character.
This will fire mainly when called by the trigger for login (above).
*/ */
CREATE OR REPLACE FUNCTION fn_weaponstatsession_updateOnDelete() CREATE OR REPLACE FUNCTION fn_weaponstatsession_updateOnDelete()
RETURNS TRIGGER RETURNS TRIGGER
@ -430,6 +609,7 @@ DECLARE oldKills Int;
DECLARE oldAssists Int; DECLARE oldAssists Int;
DECLARE oldFired Int; DECLARE oldFired Int;
DECLARE oldLanded Int; DECLARE oldLanded Int;
DECLARE out integer;
BEGIN BEGIN
avatarId := OLD.avatar_id; avatarId := OLD.avatar_id;
weaponId := OLD.weapon_id; weaponId := OLD.weapon_id;
@ -437,17 +617,168 @@ BEGIN
oldAssists := OLD.assists; oldAssists := OLD.assists;
oldFired := OLD.shots_fired; oldFired := OLD.shots_fired;
oldLanded := OLD.shots_landed; oldLanded := OLD.shots_landed;
out := proc_weaponstat_addEntryIfNone(avatarId, weaponId);
UPDATE weaponstat UPDATE weaponstat
SET kills = kills + oldKills, SET kills = kills + oldKills,
assists = assists + oldAssists, assists = assists + oldAssists,
shots_fired = shots_fired + oldFired, shots_fired = shots_fired + oldFired,
shots_landed = shots_landed + oldLanded shots_landed = shots_landed + oldLanded
WHERE avatar_id = avatarId AND weapon_id = weaponId; WHERE avatar_id = avatarId AND weapon_id = weaponId;
RETURN OLD;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE OR REPLACE TRIGGER psf_weaponstatsession_updateOnDelete CREATE TRIGGER psf_weaponstatsession_updateOnDelete
BEFORE DELETE BEFORE DELETE
ON weaponstatsession ON weaponstatsession
FOR EACH ROW FOR EACH ROW
EXECUTE FUNCTION fn_weaponstatsession_updateOnDelete(); EXECUTE FUNCTION fn_weaponstatsession_updateOnDelete();
/*
Before inserting a value into the weaponstatsession table to session id -1,
correct the session id to the most current session id,
and invalidate the attempted insertion at that -1 session id.
*/
CREATE OR REPLACE FUNCTION fn_weaponstatsession_beforeInsert()
RETURNS TRIGGER
AS
$$
DECLARE avatarId Int;
DECLARE weaponId Int;
DECLARE sessionId Int;
DECLARE oldAssists Int;
DECLARE oldFired Int;
DECLARE oldLanded Int;
DECLARE out integer;
BEGIN
avatarId := NEW.avatar_id;
weaponId := NEW.weapon_id;
oldAssists := NEW.assists;
oldFired := NEW.shots_fired;
oldLanded := NEW.shots_landed;
sessionId := proc_sessionnumber_get(avatarId);
out := proc_weaponstatsession_addEntryIfNoneWithSessionId(avatarId, weaponId, sessionId);
BEGIN
UPDATE weaponstatsession
SET
assists = assists + oldAssists,
shots_fired = shots_fired + oldFired,
shots_landed = shots_landed + oldLanded
WHERE avatar_id = avatarId AND session_id = sessionId AND weapon_id = weaponId;
END;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER psf_weaponstatsession_beforeInsert
BEFORE INSERT
ON weaponstatsession
FOR EACH ROW
WHEN (NEW.session_id = -1)
EXECUTE FUNCTION fn_weaponstatsession_beforeInsert();
/*
A kill assist activity causes a major update to weapon stats:
the weapon that was used in the activity has the kills count for the killer updated/increased.
*/
CREATE OR REPLACE FUNCTION fn_assistactivity_updateRelatedStats()
RETURNS TRIGGER
AS
$$
DECLARE killerSessionId Int;
DECLARE killerId Int;
DECLARE weaponId Int;
DECLARE out integer;
BEGIN
killerId := NEW.killer_id;
weaponId := NEW.weapon_id;
killerSessionId := proc_sessionnumber_get(killerId);
out := proc_weaponstatsession_addEntryIfNone(killerId, killerSessionId, weaponId);
BEGIN
UPDATE weaponstatsession
SET assists = assists + 1
WHERE avatar_id = killerId AND session_id = killerSessionId AND weapon_id = weaponId;
END;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER psf_assistactivity_updateRelatedStats
AFTER INSERT
ON killactivity
FOR EACH ROW
EXECUTE FUNCTION fn_assistactivity_updateRelatedStats();
/*
Upon deletion of row entries for a character's building capture table,
the values are copied over to a total capture record for that character.
This will sort the values into one of two tables, and,
for one table, it will add to either one column or to a different column.
*/
CREATE OR REPLACE FUNCTION fn_buildingcapture_updateOnDelete()
RETURNS TRIGGER
AS
$$
DECLARE oldAvatarId Int;
DECLARE oldZoneId Int;
DECLARE oldBuildingId Int;
DECLARE oldExp Int;
DECLARE oldType CHAR(3);
DECLARE out integer;
BEGIN
oldAvatarId := NEW.avatar_id;
oldZoneId := NEW.zone_id;
oldBuildingId := NEW.building_id;
oldExp := NEW.exp;
oldType := NEW.exp_type;
BEGIN
IF (oldType LIKE "bep") THEN
out := proc_expbuildingcapture_addEntryIfNone(avatarId, buildingId, zoneId);
UPDATE expbuildingcapture
SET bep = bep + oldExp
WHERE avatar_id = oldAvatarId AND zone_id = oldZOneId AND building_id = oldBuildingId;
ELSIF (oldType LIKE "cep") THEN
out := proc_expbuildingcapture_addEntryIfNone(avatarId, buildingId, zoneId);
UPDATE expbuildingcapture
SET cep = cep + oldExp
WHERE avatar_id = oldAvatarId AND zone_id = oldZOneId AND building_id = oldBuildingId;
ELSIF (oldType LIKE "llu") THEN
out := proc_llubuildingcapture_addEntryIfNone(avatarId, buildingId, zoneId);
UPDATE llubuildingcapture
SET exp = exp + oldExp
WHERE avatar_id = oldAvatarId AND zone_id = oldZOneId AND building_id = oldBuildingId;
END IF;
END;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER psf_buildingcapture_updateOnDelete
BEFORE DELETE
ON buildingcapture
FOR EACH ROW
EXECUTE FUNCTION fn_buildingcapture_updateOnDelete();
/*
If a new avatar is created, a corresponding progression debt entry is also created by default.
*/
CREATE OR REPLACE FUNCTION fn_avatar_addDebtEntry()
RETURNS TRIGGER
AS
$$
DECLARE newAvatarId Int;
BEGIN
newAvatarId := NEW.avatar_id;
BEGIN
INSERT INTO progressiondebt (avatar_id)
VALUES (newAvatarId);
END;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER psf_avatar_addDebtEntry
AFTER INSERT
ON avatar
FOR EACH ROW
EXECUTE FUNCTION fn_avatar_addDebtEntry();

View file

@ -14,7 +14,7 @@ END;
$function$ $function$
; ;
CREATE OR REPLACE TRIGGER trigger_accounts_set_token_created CREATE TRIGGER trigger_accounts_set_token_created
BEFORE UPDATE BEFORE UPDATE
OF "token" ON "account" OF "token" ON "account"
FOR EACH ROW EXECUTE FUNCTION fn_set_token_created_timestamp(); FOR EACH ROW EXECUTE FUNCTION fn_set_token_created_timestamp();