Skip to content

Commit

Permalink
port BSQL update
Browse files Browse the repository at this point in the history
  • Loading branch information
maaacha committed May 16, 2024
1 parent d41f7d9 commit a878006
Show file tree
Hide file tree
Showing 50 changed files with 3,815 additions and 1,569 deletions.
29 changes: 29 additions & 0 deletions .dockerignore
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
.dockerignore
.editorconfig
.travis.yml
GPLv3.txt
LICENSE
README.md
TGS3.json
.github
.gitignore
.gitattributes
.git/hooks
.git/info
.git/modules
.git/objects
.git/refs
.vs*
cfg
data
SQL
tgui/node_modules
tgstation.dmb
tgstation.int
tgstation.rsc
tgstation.lk
tgstation.dyn.rsc
libmariadb.dll
rust_g.dll
appveyor.yml
Dockerfile
Binary file removed BSQL.dll
Binary file not shown.
110 changes: 107 additions & 3 deletions SQL/database_changelog.txt
Original file line number Diff line number Diff line change
@@ -1,13 +1,117 @@
Any time you make a change to the schema files, remember to increment the database schema version. Generally increment the minor number, major should be reserved for significant changes to the schema. Both values go up to 255.

The latest database version is 5.3; The query to update the schema revision table is:
The latest database version is 5.9; The query to update the schema revision table is:

INSERT INTO `schema_revision` (`major`, `minor`) VALUES (5, 3);
INSERT INTO `schema_revision` (`major`, `minor`) VALUES (5, 9);
or
INSERT INTO `SS13_schema_revision` (`major`, `minor`) VALUES (5, 3);
INSERT INTO `SS13_schema_revision` (`major`, `minor`) VALUES (5, 9);

In any query remember to add a prefix to the table names if you use one.

-----------------------------------------------------

Version 5.9, 19 April 2020, by Jordie0608
Updates and improvements to poll handling.
Added the `deleted` column to tables 'poll_option', 'poll_textreply' and 'poll_vote' and the columns `created_datetime`, `subtitle`, `allow_revoting` and `deleted` to 'poll_question'.
Changes table 'poll_question' column `createdby_ckey` to be NOT NULL and index `idx_pquest_time_admin` to be `idx_pquest_time_deleted_id` and 'poll_textreply' column `adminrank` to have no default.
Added procedure `set_poll_deleted` that's called when deleting a poll to set deleted to true on each poll table where rows matching a poll_id argument.

ALTER TABLE `poll_option`
ADD COLUMN `deleted` TINYINT(1) UNSIGNED NOT NULL DEFAULT '0' AFTER `default_percentage_calc`;

ALTER TABLE `poll_question`
CHANGE COLUMN `createdby_ckey` `createdby_ckey` VARCHAR(32) NOT NULL AFTER `multiplechoiceoptions`,
ADD COLUMN `created_datetime` datetime NOT NULL AFTER `polltype`,
ADD COLUMN `subtitle` VARCHAR(255) NULL DEFAULT NULL AFTER `question`,
ADD COLUMN `allow_revoting` TINYINT(1) UNSIGNED NOT NULL AFTER `dontshow`,
ADD COLUMN `deleted` TINYINT(1) UNSIGNED NOT NULL DEFAULT '0' AFTER `allow_revoting`,
DROP INDEX `idx_pquest_time_admin`,
ADD INDEX `idx_pquest_time_deleted_id` (`starttime`, `endtime`, `deleted`, `id`);

ALTER TABLE `poll_textreply`
CHANGE COLUMN `adminrank` `adminrank` varchar(32) NOT NULL AFTER `replytext`,
ADD COLUMN `deleted` TINYINT(1) UNSIGNED NOT NULL DEFAULT '0' AFTER `adminrank`;

ALTER TABLE `poll_vote`
ADD COLUMN `deleted` TINYINT(1) UNSIGNED NOT NULL DEFAULT '0' AFTER `rating`;

DELIMITER $$
CREATE PROCEDURE `set_poll_deleted`(
IN `poll_id` INT
)
SQL SECURITY INVOKER
BEGIN
UPDATE `poll_question` SET deleted = 1 WHERE id = poll_id;
UPDATE `poll_option` SET deleted = 1 WHERE pollid = poll_id;
UPDATE `poll_vote` SET deleted = 1 WHERE pollid = poll_id;
UPDATE `poll_textreply` SET deleted = 1 WHERE pollid = poll_id;
END
$$
DELIMITER ;

-----------------------------------------------------

Version 5.8, 7 April 2020, by Jordie0608
Modified table `messages`, adding column `deleted_ckey` to record who deleted a message.

ALTER TABLE `messages` ADD COLUMN `deleted_ckey` VARCHAR(32) NULL DEFAULT NULL AFTER `deleted`;

-----------------------------------------------------

Version 5.7, 10 January 2020 by Atlanta-Ned
Added ticket table for tracking ahelp tickets in the database.

DROP TABLE IF EXISTS `ticket`;
CREATE TABLE `ticket` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`server_ip` int(10) unsigned NOT NULL,
`server_port` smallint(5) unsigned NOT NULL,
`round_id` int(11) unsigned NOT NULL,
`ticket` smallint(11) unsigned NOT NULL,
`action` varchar(20) NOT NULL DEFAULT 'Message',
`message` text NOT NULL,
`timestamp` datetime NOT NULL,
`recipient` varchar(32) DEFAULT NULL,
`sender` varchar(32) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;

-----------------------------------------------------

Version 5.6, 6 December 2019 by Anturke
Added achievement_name and achievement_description columns to achievement_metadata table.


ALTER TABLE `achievement_metadata` ADD COLUMN (`achievement_name` VARCHAR(64) NULL DEFAULT NULL, `achievement_description` VARCHAR(512) NULL DEFAULT NULL);

-----------------------------------------------------

Version 5.5, 26 October 2019 by Anturke
Added achievement_metadata table.

DROP TABLE IF EXISTS `achievement_metadata`;
CREATE TABLE `achievement_metadata` (
`achievement_key` VARCHAR(32) NOT NULL,
`achievement_version` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`achievement_type` enum('achievement','score','award') NULL DEFAULT NULL,
PRIMARY KEY (`achievement_key`)
) ENGINE=InnoDB;


-----------------------------------------------------

Version 5.4, 5 October 2019 by Anturke
Added achievements table.
See hub migration verb in _achievement_data.dm for details on migrating.

CREATE TABLE `achievements` (
`ckey` VARCHAR(32) NOT NULL,
`achievement_key` VARCHAR(32) NOT NULL,
`value` INT NULL,
`last_updated` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`ckey`,`achievement_key`)
) ENGINE=InnoDB;

----------------------------------------------------

Version 5.3, 6 July 2019, by Atlanta-Ned
Expand Down
89 changes: 74 additions & 15 deletions SQL/tgstation_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -258,6 +258,7 @@ CREATE TABLE `messages` (
`lasteditor` varchar(32) DEFAULT NULL,
`edits` text,
`deleted` tinyint(1) unsigned NOT NULL DEFAULT '0',
`deleted_ckey` VARCHAR(32) NULL DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_msg_ckey_time` (`targetckey`,`timestamp`, `deleted`),
KEY `idx_msg_type_ckeys_time` (`type`,`targetckey`,`adminckey`,`timestamp`, `deleted`),
Expand Down Expand Up @@ -345,6 +346,7 @@ CREATE TABLE `poll_option` (
`descmid` varchar(32) DEFAULT NULL,
`descmax` varchar(32) DEFAULT NULL,
`default_percentage_calc` tinyint(1) unsigned NOT NULL DEFAULT '1',
`deleted` tinyint(1) unsigned NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
KEY `idx_pop_pollid` (`pollid`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
Expand All @@ -360,17 +362,21 @@ DROP TABLE IF EXISTS `poll_question`;
CREATE TABLE `poll_question` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`polltype` enum('OPTION','TEXT','NUMVAL','MULTICHOICE','IRV') NOT NULL,
`created_datetime` datetime NOT NULL,
`starttime` datetime NOT NULL,
`endtime` datetime NOT NULL,
`question` varchar(255) NOT NULL,
`subtitle` varchar(255) DEFAULT NULL,
`adminonly` tinyint(1) unsigned NOT NULL,
`multiplechoiceoptions` int(2) DEFAULT NULL,
`createdby_ckey` varchar(32) DEFAULT NULL,
`createdby_ckey` varchar(32) NOT NULL,
`createdby_ip` int(10) unsigned NOT NULL,
`dontshow` tinyint(1) unsigned NOT NULL,
`allow_revoting` tinyint(1) unsigned NOT NULL,
`deleted` tinyint(1) unsigned NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
KEY `idx_pquest_question_time_ckey` (`question`,`starttime`,`endtime`,`createdby_ckey`,`createdby_ip`),
KEY `idx_pquest_time_admin` (`starttime`,`endtime`,`adminonly`),
KEY `idx_pquest_time_deleted_id` (`starttime`,`endtime`, `deleted`, `id`),
KEY `idx_pquest_id_time_type_admin` (`id`,`starttime`,`endtime`,`polltype`,`adminonly`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
/*!40101 SET character_set_client = @saved_cs_client */;
Expand All @@ -389,7 +395,8 @@ CREATE TABLE `poll_textreply` (
`ckey` varchar(32) NOT NULL,
`ip` int(10) unsigned NOT NULL,
`replytext` varchar(2048) NOT NULL,
`adminrank` varchar(32) NOT NULL DEFAULT 'Player',
`adminrank` varchar(32) NOT NULL,
`deleted` tinyint(1) unsigned NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
KEY `idx_ptext_pollid_ckey` (`pollid`,`ckey`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
Expand All @@ -411,6 +418,7 @@ CREATE TABLE `poll_vote` (
`ip` int(10) unsigned NOT NULL,
`adminrank` varchar(32) NOT NULL,
`rating` int(2) DEFAULT NULL,
`deleted` tinyint(1) unsigned NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
KEY `idx_pvote_pollid_ckey` (`pollid`,`ckey`),
KEY `idx_pvote_optionid_ckey` (`optionid`,`ckey`)
Expand Down Expand Up @@ -454,18 +462,6 @@ CREATE TABLE `schema_revision` (
PRIMARY KEY (`major`, `minor`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;

DELIMITER $$
CREATE TRIGGER `role_timeTlogupdate` AFTER UPDATE ON `role_time` FOR EACH ROW BEGIN INSERT into role_time_log (ckey, job, delta) VALUES (NEW.CKEY, NEW.job, NEW.minutes-OLD.minutes);
END
$$
CREATE TRIGGER `role_timeTloginsert` AFTER INSERT ON `role_time` FOR EACH ROW BEGIN INSERT into role_time_log (ckey, job, delta) VALUES (NEW.ckey, NEW.job, NEW.minutes);
END
$$
CREATE TRIGGER `role_timeTlogdelete` AFTER DELETE ON `role_time` FOR EACH ROW BEGIN INSERT into role_time_log (ckey, job, delta) VALUES (OLD.ckey, OLD.job, 0-OLD.minutes);
END
$$
DELIMITER ;

--
-- Table structure for table `stickyban`
--
Expand Down Expand Up @@ -515,6 +511,69 @@ CREATE TABLE `stickyban_matched_cid` (
PRIMARY KEY (`stickyban`, `matched_cid`)
) ENGINE=InnoDB;

--
-- Table structure for table `achievements`
--
DROP TABLE IF EXISTS `achievements`;
CREATE TABLE `achievements` (
`ckey` VARCHAR(32) NOT NULL,
`achievement_key` VARCHAR(32) NOT NULL,
`value` INT NULL,
`last_updated` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`ckey`,`achievement_key`)
) ENGINE=InnoDB;

DROP TABLE IF EXISTS `achievement_metadata`;
CREATE TABLE `achievement_metadata` (
`achievement_key` VARCHAR(32) NOT NULL,
`achievement_version` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`achievement_type` enum('achievement','score','award') NULL DEFAULT NULL,
`achievement_name` VARCHAR(64) NULL DEFAULT NULL,
`achievement_description` VARCHAR(512) NULL DEFAULT NULL,
PRIMARY KEY (`achievement_key`)
) ENGINE=InnoDB;

--
-- Table structure for table `ticket`
--
DROP TABLE IF EXISTS `ticket`;
CREATE TABLE `ticket` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`server_ip` int(10) unsigned NOT NULL,
`server_port` smallint(5) unsigned NOT NULL,
`round_id` int(11) unsigned NOT NULL,
`ticket` smallint(11) unsigned NOT NULL,
`action` varchar(20) NOT NULL DEFAULT 'Message',
`message` text NOT NULL,
`timestamp` datetime NOT NULL,
`recipient` varchar(32) DEFAULT NULL,
`sender` varchar(32) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;

DELIMITER $$
CREATE PROCEDURE `set_poll_deleted`(
IN `poll_id` INT
)
SQL SECURITY INVOKER
BEGIN
UPDATE `poll_question` SET deleted = 1 WHERE id = poll_id;
UPDATE `poll_option` SET deleted = 1 WHERE pollid = poll_id;
UPDATE `poll_vote` SET deleted = 1 WHERE pollid = poll_id;
UPDATE `poll_textreply` SET deleted = 1 WHERE pollid = poll_id;
END
$$
CREATE TRIGGER `role_timeTlogupdate` AFTER UPDATE ON `role_time` FOR EACH ROW BEGIN INSERT into role_time_log (ckey, job, delta) VALUES (NEW.CKEY, NEW.job, NEW.minutes-OLD.minutes);
END
$$
CREATE TRIGGER `role_timeTloginsert` AFTER INSERT ON `role_time` FOR EACH ROW BEGIN INSERT into role_time_log (ckey, job, delta) VALUES (NEW.ckey, NEW.job, NEW.minutes);
END
$$
CREATE TRIGGER `role_timeTlogdelete` AFTER DELETE ON `role_time` FOR EACH ROW BEGIN INSERT into role_time_log (ckey, job, delta) VALUES (OLD.ckey, OLD.job, 0-OLD.minutes);
END
$$
DELIMITER ;

/*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
/*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */;
Expand Down
Loading

0 comments on commit a878006

Please sign in to comment.