diff --git a/SQL/database_changelog.txt b/SQL/database_changelog.txt index bf765a0806d..4c4638295b0 100644 --- a/SQL/database_changelog.txt +++ b/SQL/database_changelog.txt @@ -1,3 +1,13 @@ +19 February 2017, by Jordie0608 + +Optimised and indexed significant portions of the schema. + +See the file 'optimisations_2017-02-19.sql' for instructions on how to apply these changes to your database. + +Remember to add a prefix to the table name if you use them + +---------------------------------------------------- + 30 January 2017, by Lzimann Modified table 'death', adding the columns 'mapname' and 'server'. diff --git a/SQL/optimisations_2017-02-19.sql b/SQL/optimisations_2017-02-19.sql new file mode 100644 index 00000000000..22c4234cf06 --- /dev/null +++ b/SQL/optimisations_2017-02-19.sql @@ -0,0 +1,198 @@ +/* +It is recommended you do not perfom any of these queries while your server is live as they will lock the tables during execution. + +Backup your database before starting; Breaking errors may occur when old data is not be compatible with new column formats. +i.e. A field that is null or empty due to rows existing before the column was added, data corruption or incorrect inputs will prevent altering the column to be NOT NULL. +To account where this is likely to occur, these queries check if fields have valid data and if not will replace invalid data with 0. +Some fields may be out of range for new column lengths, this will also cause a breaking error. +For instance `death`.`bruteloss` is now SMALLINT and won't accept any values over 65535. +Data in this table can thus be truncated using a query such as: +UPDATE `[database]`.`[table]` SET `[column]` = LEAST(`[column]`, [max column size]) +To truncate a text field you would have to use SUBSTRING(), however I don't suggest you truncate any text fields. +If you wish to instead preserve this data you will need to modify the schema and queries to accomodate. + +Take note some columns have been renamed, removed or changed type. Any services relying on these columns will have to be updated per changes. + +----------------------------------------------------*/ + +START TRANSACTION; +ALTER TABLE `feedback`.`ban` + DROP COLUMN `rounds` +, CHANGE COLUMN `bantype` `bantype` ENUM('PERMABAN', 'TEMPBAN', 'JOB_PERMABAN', 'JOB_TEMPBAN', 'ADMIN_PERMABAN', 'ADMIN_TEMPBAN') NOT NULL +, CHANGE COLUMN `reason` `reason` VARCHAR(2048) NOT NULL +, CHANGE COLUMN `who` `who` VARCHAR(2048) NOT NULL +, CHANGE COLUMN `adminwho` `adminwho` VARCHAR(2048) NOT NULL +, CHANGE COLUMN `unbanned` `unbanned` TINYINT UNSIGNED NULL DEFAULT NULL +, ADD COLUMN `server_ip` INT UNSIGNED NOT NULL AFTER `serverip` +, ADD COLUMN `server_port` SMALLINT UNSIGNED NOT NULL AFTER `server_ip` +, ADD COLUMN `ipTEMP` INT UNSIGNED NOT NULL AFTER `ip` +, ADD COLUMN `a_ipTEMP` INT UNSIGNED NOT NULL AFTER `a_ip` +, ADD COLUMN `unbanned_ipTEMP` INT UNSIGNED NULL DEFAULT NULL AFTER `unbanned_ip`; +SET SQL_SAFE_UPDATES = 0; +UPDATE `feedback`.`ban` + SET `server_ip` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`serverip`, ':', 1)), ''), INET_ATON('0.0.0.0')) +, `server_port` = IF(`serverip` LIKE '%:_%', CAST(SUBSTRING_INDEX(`serverip`, ':', -1) AS UNSIGNED), '0') +, `ipTEMP` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`ip`, ':', 1)), ''), INET_ATON('0.0.0.0')) +, `a_ipTEMP` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`a_ip`, ':', 1)), ''), INET_ATON('0.0.0.0')) +, `unbanned_ipTEMP` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`unbanned_ip`, ':', 1)), ''), INET_ATON('0.0.0.0')); +SET SQL_SAFE_UPDATES = 1; +ALTER TABLE `feedback`.`ban` + DROP COLUMN `unbanned_ip` +, DROP COLUMN `a_ip` +, DROP COLUMN `ip` +, DROP COLUMN `serverip` +, CHANGE COLUMN `ipTEMP` `ip` INT(10) UNSIGNED NOT NULL +, CHANGE COLUMN `a_ipTEMP` `a_ip` INT(10) UNSIGNED NOT NULL +, CHANGE COLUMN `unbanned_ipTEMP` `unbanned_ip` INT(10) UNSIGNED NULL DEFAULT NULL; +COMMIT; + +START TRANSACTION; +ALTER TABLE `feedback`.`connection_log` + ADD COLUMN `server_ip` INT UNSIGNED NOT NULL AFTER `serverip` +, ADD COLUMN `server_port` SMALLINT UNSIGNED NOT NULL AFTER `server_ip` +, ADD COLUMN `ipTEMP` INT UNSIGNED NOT NULL AFTER `ip`; +SET SQL_SAFE_UPDATES = 0; +UPDATE `feedback`.`connection_log` + SET `server_ip` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`serverip`, ':', 1)), ''), INET_ATON('0.0.0.0')) +, `server_port` = IF(`serverip` LIKE '%:_%', CAST(SUBSTRING_INDEX(`serverip`, ':', -1) AS UNSIGNED), '0') +, `ipTEMP` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`ip`, ':', 1)), ''), INET_ATON('0.0.0.0')); +SET SQL_SAFE_UPDATES = 1; +ALTER TABLE `feedback`.`connection_log` + DROP COLUMN `ip` +, DROP COLUMN `serverip` +, CHANGE COLUMN `ipTEMP` `ip` INT(10) UNSIGNED NOT NULL; +COMMIT; + +START TRANSACTION; +SET SQL_SAFE_UPDATES = 0; +UPDATE `feedback`.`death` + SET `bruteloss` = LEAST(`bruteloss`, 65535) +, `brainloss` = LEAST(`brainloss`, 65535) +, `fireloss` = LEAST(`fireloss`, 65535) +, `oxyloss` = LEAST(`oxyloss`, 65535); +ALTER TABLE `feedback`.`death` + CHANGE COLUMN `pod` `pod` VARCHAR(50) NOT NULL +, CHANGE COLUMN `coord` `coord` VARCHAR(32) NOT NULL +, CHANGE COLUMN `mapname` `mapname` VARCHAR(32) NOT NULL +, CHANGE COLUMN `job` `job` VARCHAR(32) NOT NULL +, CHANGE COLUMN `special` `special` VARCHAR(32) NULL DEFAULT NULL +, CHANGE COLUMN `name` `name` VARCHAR(96) NOT NULL +, CHANGE COLUMN `byondkey` `byondkey` VARCHAR(32) NOT NULL +, CHANGE COLUMN `laname` `laname` VARCHAR(96) NULL DEFAULT NULL +, CHANGE COLUMN `lakey` `lakey` VARCHAR(32) NULL DEFAULT NULL +, CHANGE COLUMN `gender` `gender` ENUM('neuter', 'male', 'female', 'plural') NOT NULL +, CHANGE COLUMN `bruteloss` `bruteloss` SMALLINT UNSIGNED NOT NULL +, CHANGE COLUMN `brainloss` `brainloss` SMALLINT UNSIGNED NOT NULL +, CHANGE COLUMN `fireloss` `fireloss` SMALLINT UNSIGNED NOT NULL +, CHANGE COLUMN `oxyloss` `oxyloss` SMALLINT UNSIGNED NOT NULL +, ADD COLUMN `server_ip` INT UNSIGNED NOT NULL AFTER `server` +, ADD COLUMN `server_port` SMALLINT UNSIGNED NOT NULL AFTER `server_ip`; +UPDATE `feedback`.`death` + SET `server_ip` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`server`, ':', 1)), ''), INET_ATON('0.0.0.0')) +, `server_port` = IF(`server` LIKE '%:_%', CAST(SUBSTRING_INDEX(`server`, ':', -1) AS UNSIGNED), '0'); +SET SQL_SAFE_UPDATES = 1; +ALTER TABLE `feedback`.`death` + DROP COLUMN `server`; +COMMIT; + +ALTER TABLE `feedback`.`library` + CHANGE COLUMN `category` `category` ENUM('Any', 'Fiction', 'Non-Fiction', 'Adult', 'Reference', 'Religion') NOT NULL +, CHANGE COLUMN `ckey` `ckey` VARCHAR(32) NOT NULL DEFAULT 'LEGACY' +, CHANGE COLUMN `datetime` `datetime` DATETIME NOT NULL +, CHANGE COLUMN `deleted` `deleted` TINYINT(1) UNSIGNED NULL DEFAULT NULL; + +ALTER TABLE `feedback`.`messages` + CHANGE COLUMN `type` `type` ENUM('memo', 'message', 'message sent', 'note', 'watchlist entry') NOT NULL +, CHANGE COLUMN `text` `text` VARCHAR(2048) NOT NULL +, CHANGE COLUMN `secret` `secret` TINYINT(1) UNSIGNED NOT NULL; + +START TRANSACTION; +ALTER TABLE `feedback`.`player` + ADD COLUMN `ipTEMP` INT UNSIGNED NOT NULL AFTER `ip`; +SET SQL_SAFE_UPDATES = 0; +UPDATE `feedback`.`player` + SET `ipTEMP` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`ip`, ':', 1)), ''), INET_ATON('0.0.0.0')); +SET SQL_SAFE_UPDATES = 1; +ALTER TABLE `feedback`.`player` + DROP COLUMN `ip` +, CHANGE COLUMN `ipTEMP` `ip` INT(10) UNSIGNED NOT NULL; +COMMIT; + +ALTER TABLE `feedback`.`poll_question` + CHANGE COLUMN `polltype` `polltype` ENUM('OPTION', 'TEXT', 'NUMVAL', 'MULTICHOICE', 'IRV') NOT NULL +, CHANGE COLUMN `adminonly` `adminonly` TINYINT(1) UNSIGNED NOT NULL +, CHANGE COLUMN `createdby_ckey` `createdby_ckey` VARCHAR(32) NULL DEFAULT NULL +, CHANGE COLUMN `createdby_ip` `createdby_ip` VARCHAR(32) NULL DEFAULT NULL +, CHANGE COLUMN `for_trialmin` `for_trialmin` VARCHAR(32) NULL DEFAULT NULL +, CHANGE COLUMN `dontshow` `dontshow` TINYINT(1) UNSIGNED NOT NULL; + +START TRANSACTION; +ALTER TABLE `feedback`.`poll_textreply` + CHANGE COLUMN `replytext` `replytext` VARCHAR(2048) NOT NULL +, ADD COLUMN `ipTEMP` INT UNSIGNED NOT NULL AFTER `ip`; +SET SQL_SAFE_UPDATES = 0; +UPDATE `feedback`.`poll_textreply` + SET `ipTEMP` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`ip`, ':', 1)), ''), INET_ATON('0.0.0.0')); +SET SQL_SAFE_UPDATES = 1; +ALTER TABLE `feedback`.`poll_textreply` + DROP COLUMN `ip` +, CHANGE COLUMN `ipTEMP` `ip` INT(10) UNSIGNED NOT NULL; +COMMIT; + +START TRANSACTION; +ALTER TABLE `feedback`.`poll_vote` + CHANGE COLUMN `ckey` `ckey` VARCHAR(32) NOT NULL +, ADD COLUMN `ipTEMP` INT UNSIGNED NOT NULL AFTER `ip`; +SET SQL_SAFE_UPDATES = 0; +UPDATE `feedback`.`poll_vote` + SET `ipTEMP` = COALESCE(NULLIF(INET_ATON(SUBSTRING_INDEX(`ip`, ':', 1)), ''), INET_ATON('0.0.0.0')); +SET SQL_SAFE_UPDATES = 1; +ALTER TABLE `feedback`.`poll_vote` + DROP COLUMN `ip` +, CHANGE COLUMN `ipTEMP` `ip` INT(10) UNSIGNED NOT NULL; +COMMIT; + +/*---------------------------------------------------- + +These queries are to be run after the above. +These indexes are designed with only the codebase queries in mind. +You may find it helpful to modify or create your own indexes if you utilise additional queries for other services. + +----------------------------------------------------*/ + +ALTER TABLE `feedback`.`ban` + ADD INDEX `idx_ban_checkban` (`ckey` ASC, `bantype` ASC, `expiration_time` ASC, `unbanned` ASC, `job` ASC) +, ADD INDEX `idx_ban_isbanned` (`ckey` ASC, `ip` ASC, `computerid` ASC, `bantype` ASC, `expiration_time` ASC, `unbanned` ASC) +, ADD INDEX `idx_ban_count` (`id` ASC, `a_ckey` ASC, `bantype` ASC, `expiration_time` ASC, `unbanned` ASC); + +ALTER TABLE `feedback`.`ipintel` + ADD INDEX `idx_ipintel` (`ip` ASC, `intel` ASC, `date` ASC); + +ALTER TABLE `feedback`.`library` + ADD INDEX `idx_lib_id_del` (`id` ASC, `deleted` ASC) +, ADD INDEX `idx_lib_del_title` (`deleted` ASC, `title` ASC) +, ADD INDEX `idx_lib_search` (`deleted` ASC, `author` ASC, `title` ASC, `category` ASC); + +ALTER TABLE `feedback`.`messages` + ADD INDEX `idx_msg_ckey_time` (`targetckey` ASC, `timestamp` ASC) +, ADD INDEX `idx_msg_type_ckeys_time` (`type` ASC, `targetckey` ASC, `adminckey` ASC, `timestamp` ASC) +, ADD INDEX `idx_msg_type_ckey_time_odr` (`type` ASC, `targetckey` ASC, `timestamp` ASC); + +ALTER TABLE `feedback`.`player` + ADD INDEX `idx_player_cid_ckey` (`computerid` ASC, `ckey` ASC) +, ADD INDEX `idx_player_ip_ckey` (`ip` ASC, `ckey` ASC); + +ALTER TABLE `feedback`.`poll_option` + ADD INDEX `idx_pop_pollid` (`pollid` ASC); + +ALTER TABLE `feedback`.`poll_question` + ADD INDEX `idx_pquest_question_time_ckey` (`question` ASC, `starttime` ASC, `endtime` ASC, `createdby_ckey` ASC, `createdby_ip` ASC) +, ADD INDEX `idx_pquest_time_admin` (`starttime` ASC, `endtime` ASC, `adminonly` ASC) +, ADD INDEX `idx_pquest_id_time_type_admin` (`id` ASC, `starttime` ASC, `endtime` ASC, `polltype` ASC, `adminonly` ASC); + +ALTER TABLE `feedback`.`poll_vote` + ADD INDEX `idx_pvote_pollid_ckey` (`pollid` ASC, `ckey` ASC) +, ADD INDEX `idx_pvote_optionid_ckey` (`optionid` ASC, `ckey` ASC); + +ALTER TABLE `feedback`.`poll_textreply` + ADD INDEX `idx_ptext_pollid_ckey` (`pollid` ASC, `ckey` ASC); diff --git a/SQL/tgstation_schema.sql b/SQL/tgstation_schema.sql index e751b130890..4ccae0eecdb 100644 --- a/SQL/tgstation_schema.sql +++ b/SQL/tgstation_schema.sql @@ -59,18 +59,9 @@ CREATE TABLE `admin_ranks` ( `rank` varchar(40) NOT NULL, `flags` int(16) NOT NULL DEFAULT '0', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=latin1; +) ENGINE=InnoDB AUTO_INCREMENT=9 DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; -insert into admin_ranks (rank, flags) values ('Moderator',2); -insert into admin_ranks (rank, flags) values ('Admin Candidate',2); -insert into admin_ranks (rank, flags) values ('Trial Admin',5638); -insert into admin_ranks (rank, flags) values ('Badmin',5727); -insert into admin_ranks (rank, flags) values ('Game Admin',8063); -insert into admin_ranks (rank, flags) values ('Game Master',65535); -insert into admin_ranks (rank, flags) values ('Host',65535); -insert into admin_ranks (rank, flags) values ('Coder',5168); - -- -- Table structure for table `ban` -- @@ -81,28 +72,31 @@ DROP TABLE IF EXISTS `ban`; CREATE TABLE `ban` ( `id` int(11) NOT NULL AUTO_INCREMENT, `bantime` datetime NOT NULL, - `serverip` varchar(32) NOT NULL, - `bantype` varchar(32) NOT NULL, - `reason` text NOT NULL, + `server_ip` int(10) unsigned NOT NULL, + `server_port` smallint(5) unsigned NOT NULL, + `bantype` enum('PERMABAN','TEMPBAN','JOB_PERMABAN','JOB_TEMPBAN','ADMIN_PERMABAN','ADMIN_TEMPBAN') NOT NULL, + `reason` varchar(2048) NOT NULL, `job` varchar(32) DEFAULT NULL, `duration` int(11) NOT NULL, - `rounds` int(11) DEFAULT NULL, `expiration_time` datetime NOT NULL, `ckey` varchar(32) NOT NULL, `computerid` varchar(32) NOT NULL, - `ip` varchar(32) NOT NULL, + `ip` int(10) unsigned NOT NULL, `a_ckey` varchar(32) NOT NULL, `a_computerid` varchar(32) NOT NULL, - `a_ip` varchar(32) NOT NULL, - `who` text NOT NULL, - `adminwho` text NOT NULL, + `a_ip` int(10) unsigned NOT NULL, + `who` varchar(2048) NOT NULL, + `adminwho` varchar(2048) NOT NULL, `edits` text, - `unbanned` int(2) DEFAULT NULL, + `unbanned` tinyint(3) unsigned DEFAULT NULL, `unbanned_datetime` datetime DEFAULT NULL, `unbanned_ckey` varchar(32) DEFAULT NULL, `unbanned_computerid` varchar(32) DEFAULT NULL, - `unbanned_ip` varchar(32) DEFAULT NULL, - PRIMARY KEY (`id`) + `unbanned_ip` int(10) unsigned DEFAULT NULL, + PRIMARY KEY (`id`), + KEY `idx_ban_checkban` (`ckey`,`bantype`,`expiration_time`,`unbanned`,`job`), + KEY `idx_ban_isbanned` (`ckey`,`ip`,`computerid`,`bantype`,`expiration_time`,`unbanned`), + KEY `idx_ban_count` (`id`,`a_ckey`,`bantype`,`expiration_time`,`unbanned`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -116,9 +110,10 @@ DROP TABLE IF EXISTS `connection_log`; CREATE TABLE `connection_log` ( `id` int(11) NOT NULL AUTO_INCREMENT, `datetime` datetime DEFAULT NULL, - `serverip` varchar(45) DEFAULT NULL, + `server_ip` int(10) unsigned NOT NULL, + `server_port` smallint(5) unsigned NOT NULL, `ckey` varchar(45) DEFAULT NULL, - `ip` varchar(18) DEFAULT NULL, + `ip` int(10) unsigned NOT NULL, `computerid` varchar(45) DEFAULT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; @@ -133,23 +128,23 @@ DROP TABLE IF EXISTS `death`; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `death` ( `id` int(11) NOT NULL AUTO_INCREMENT, - `pod` text NOT NULL COMMENT 'Place of death', - `coord` text NOT NULL COMMENT 'X, Y, Z POD', - `mapname` text NOT NULL, - `server` text NOT NULL, + `pod` varchar(50) NOT NULL, + `coord` varchar(32) NOT NULL, + `mapname` varchar(32) NOT NULL, + `server_ip` int(10) unsigned NOT NULL, + `server_port` smallint(5) unsigned NOT NULL, `tod` datetime NOT NULL COMMENT 'Time of death', - `job` text NOT NULL, - `special` text NOT NULL, - `name` text NOT NULL, - `byondkey` text NOT NULL, - `laname` text NOT NULL COMMENT 'Last attacker name', - `lakey` text NOT NULL COMMENT 'Last attacker key', - `gender` text NOT NULL, - `bruteloss` int(11) NOT NULL, - `brainloss` int(11) NOT NULL, - `fireloss` int(11) NOT NULL, - `oxyloss` int(11) NOT NULL, - + `job` varchar(32) NOT NULL, + `special` varchar(32) DEFAULT NULL, + `name` varchar(96) NOT NULL, + `byondkey` varchar(32) NOT NULL, + `laname` varchar(96) DEFAULT NULL, + `lakey` varchar(32) DEFAULT NULL, + `gender` enum('neuter','male','female','plural') NOT NULL, + `bruteloss` smallint(5) unsigned NOT NULL, + `brainloss` smallint(5) unsigned NOT NULL, + `fireloss` smallint(5) unsigned NOT NULL, + `oxyloss` smallint(5) unsigned NOT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -172,6 +167,22 @@ CREATE TABLE `feedback` ( ) ENGINE=MyISAM DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; +-- +-- Table structure for table `ipintel` +-- + +DROP TABLE IF EXISTS `ipintel`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!40101 SET character_set_client = utf8 */; +CREATE TABLE `ipintel` ( + `ip` int(10) unsigned NOT NULL, + `date` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + `intel` double NOT NULL DEFAULT '0', + PRIMARY KEY (`ip`), + KEY `idx_ipintel` (`ip`,`intel`,`date`) +) ENGINE=InnoDB DEFAULT CHARSET=latin1; +/*!40101 SET character_set_client = @saved_cs_client */; + -- -- Table structure for table `legacy_population` -- @@ -193,22 +204,49 @@ CREATE TABLE `legacy_population` ( -- DROP TABLE IF EXISTS `library`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!40101 SET character_set_client = utf8 */; CREATE TABLE `library` ( `id` int(11) NOT NULL AUTO_INCREMENT, `author` varchar(45) NOT NULL, `title` varchar(45) NOT NULL, `content` text NOT NULL, - `category` varchar(45) NOT NULL, - `ckey` varchar(45) DEFAULT 'LEGACY', - `datetime` datetime DEFAULT NULL, - `deleted` tinyint(1) DEFAULT NULL, - PRIMARY KEY (`id`) + `category` enum('Any','Fiction','Non-Fiction','Adult','Reference','Religion') NOT NULL, + `ckey` varchar(32) NOT NULL DEFAULT 'LEGACY', + `datetime` datetime NOT NULL, + `deleted` tinyint(1) unsigned DEFAULT NULL, + PRIMARY KEY (`id`), + KEY `deleted_idx` (`deleted`), + KEY `idx_lib_id_del` (`id`,`deleted`), + KEY `idx_lib_del_title` (`deleted`,`title`), + KEY `idx_lib_search` (`deleted`,`author`,`title`,`category`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; +/*!40101 SET character_set_client = @saved_cs_client */; -- --- Create an index to speed up the libary +-- Table structure for table `messages` -- -CREATE INDEX deleted_idx ON `library` (`deleted`); + +DROP TABLE IF EXISTS `messages`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!40101 SET character_set_client = utf8 */; +CREATE TABLE `messages` ( + `id` int(11) NOT NULL AUTO_INCREMENT, + `type` enum('memo','message','message sent','note','watchlist entry') NOT NULL, + `targetckey` varchar(32) NOT NULL, + `adminckey` varchar(32) NOT NULL, + `text` varchar(2048) NOT NULL, + `timestamp` datetime NOT NULL, + `server` varchar(32) DEFAULT NULL, + `secret` tinyint(1) unsigned NOT NULL, + `lasteditor` varchar(32) DEFAULT NULL, + `edits` text, + PRIMARY KEY (`id`), + KEY `idx_msg_ckey_time` (`targetckey`,`timestamp`), + KEY `idx_msg_type_ckeys_time` (`type`,`targetckey`,`adminckey`,`timestamp`), + KEY `idx_msg_type_ckey_time_odr` (`type`,`targetckey`,`timestamp`) +) ENGINE=InnoDB DEFAULT CHARSET=latin1; +/*!40101 SET character_set_client = @saved_cs_client */; -- -- Table structure for table `player` @@ -222,11 +260,13 @@ CREATE TABLE `player` ( `ckey` varchar(32) NOT NULL, `firstseen` datetime NOT NULL, `lastseen` datetime NOT NULL, - `ip` varchar(18) NOT NULL, + `ip` int(10) unsigned NOT NULL, `computerid` varchar(32) NOT NULL, `lastadminrank` varchar(32) NOT NULL DEFAULT 'Player', PRIMARY KEY (`id`), - UNIQUE KEY `ckey` (`ckey`) + UNIQUE KEY `ckey` (`ckey`), + KEY `idx_player_cid_ckey` (`computerid`,`ckey`), + KEY `idx_player_ip_ckey` (`ip`,`ckey`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -247,7 +287,8 @@ CREATE TABLE `poll_option` ( `descmin` varchar(32) DEFAULT NULL, `descmid` varchar(32) DEFAULT NULL, `descmax` varchar(32) DEFAULT NULL, - PRIMARY KEY (`id`) + PRIMARY KEY (`id`), + KEY `idx_pop_pollid` (`pollid`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -260,17 +301,20 @@ DROP TABLE IF EXISTS `poll_question`; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `poll_question` ( `id` int(11) NOT NULL AUTO_INCREMENT, - `polltype` varchar(16) NOT NULL DEFAULT 'OPTION', + `polltype` enum('OPTION','TEXT','NUMVAL','MULTICHOICE','IRV') NOT NULL, `starttime` datetime NOT NULL, `endtime` datetime NOT NULL, `question` varchar(255) NOT NULL, - `adminonly` tinyint(1) DEFAULT '0', + `adminonly` tinyint(1) unsigned NOT NULL, `multiplechoiceoptions` int(2) DEFAULT NULL, - `createdby_ckey` varchar(45) NULL DEFAULT NULL, - `createdby_ip` varchar(45) NULL DEFAULT NULL, - `for_trialmin` varchar(45) NULL DEFAULT NULL, - `dontshow` tinyint(1) NOT NULL DEFAULT '0', - PRIMARY KEY (`id`) + `createdby_ckey` varchar(32) DEFAULT NULL, + `createdby_ip` varchar(32) DEFAULT NULL, + `for_trialmin` varchar(32) DEFAULT NULL, + `dontshow` tinyint(1) unsigned NOT NULL, + 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_id_time_type_admin` (`id`,`starttime`,`endtime`,`polltype`,`adminonly`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -286,10 +330,11 @@ CREATE TABLE `poll_textreply` ( `datetime` datetime NOT NULL, `pollid` int(11) NOT NULL, `ckey` varchar(32) NOT NULL, - `ip` varchar(18) NOT NULL, - `replytext` text NOT NULL, + `ip` int(10) unsigned NOT NULL, + `replytext` varchar(2048) NOT NULL, `adminrank` varchar(32) NOT NULL DEFAULT 'Player', - PRIMARY KEY (`id`) + PRIMARY KEY (`id`), + KEY `idx_ptext_pollid_ckey` (`pollid`,`ckey`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -305,47 +350,21 @@ CREATE TABLE `poll_vote` ( `datetime` datetime NOT NULL, `pollid` int(11) NOT NULL, `optionid` int(11) NOT NULL, - `ckey` varchar(255) NOT NULL, - `ip` varchar(16) NOT NULL, + `ckey` varchar(32) NOT NULL, + `ip` int(10) unsigned NOT NULL, `adminrank` varchar(32) NOT NULL, `rating` int(2) DEFAULT NULL, - PRIMARY KEY (`id`) + PRIMARY KEY (`id`), + KEY `idx_pvote_pollid_ckey` (`pollid`,`ckey`), + KEY `idx_pvote_optionid_ckey` (`optionid`,`ckey`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; +/*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */; --- --- Table structure for table `ipintel` --- - -DROP TABLE IF EXISTS `ipintel`; -/*!40101 SET @saved_cs_client = @@character_set_client */; -/*!40101 SET character_set_client = utf8 */; -CREATE TABLE `ipintel` ( -`ip` INT UNSIGNED NOT NULL , -`date` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL , -`intel` REAL NOT NULL DEFAULT '0', -PRIMARY KEY ( `ip` ) -) ENGINE = INNODB; -/*!40101 SET character_set_client = @saved_cs_client */; - --- --- Table structure for table `messages` --- - -DROP TABLE IF EXISTS `messages`; -/*!40101 SET @saved_cs_client = @@character_set_client */; -/*!40101 SET character_set_client = utf8 */; -CREATE TABLE `messages` ( - `id` int(11) NOT NULL AUTO_INCREMENT , - `type` varchar(32) NOT NULL , - `targetckey` varchar(32) NOT NULL , - `adminckey` varchar(32) NOT NULL , - `text` text NOT NULL , - `timestamp` datetime NOT NULL , - `server` varchar(32) NULL , - `secret` tinyint(1) NULL DEFAULT 1 , - `lasteditor` varchar(32) NULL , - `edits` text NULL , - PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=latin1; -/*!40101 SET character_set_client = @saved_cs_client */; +/*!40101 SET SQL_MODE=@OLD_SQL_MODE */; +/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */; +/*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */; +/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */; +/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */; +/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */; +/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */; diff --git a/SQL/tgstation_schema_prefixed.sql b/SQL/tgstation_schema_prefixed.sql index 63d32eed08e..3899ce5698e 100644 --- a/SQL/tgstation_schema_prefixed.sql +++ b/SQL/tgstation_schema_prefixed.sql @@ -34,7 +34,7 @@ CREATE TABLE `SS13_admin` ( -- Table structure for table `SS13_admin_log` -- -DROP TABLE IF EXISTS `SS13_admin_log`; +DROP TABLE IF EXISTS `SS13_dmin_log`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `SS13_admin_log` ( @@ -59,18 +59,9 @@ CREATE TABLE `SS13_admin_ranks` ( `rank` varchar(40) NOT NULL, `flags` int(16) NOT NULL DEFAULT '0', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=latin1; +) ENGINE=InnoDB AUTO_INCREMENT=9 DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; -insert into SS13_admin_ranks (rank, flags) values ('Moderator',2); -insert into SS13_admin_ranks (rank, flags) values ('Admin Candidate',2); -insert into SS13_admin_ranks (rank, flags) values ('Trial Admin',5638); -insert into SS13_admin_ranks (rank, flags) values ('Badmin',5727); -insert into SS13_admin_ranks (rank, flags) values ('Game Admin',8063); -insert into SS13_admin_ranks (rank, flags) values ('Game Master',65535); -insert into SS13_admin_ranks (rank, flags) values ('Host',65535); -insert into SS13_admin_ranks (rank, flags) values ('Coder',5168); - -- -- Table structure for table `SS13_ban` -- @@ -81,28 +72,31 @@ DROP TABLE IF EXISTS `SS13_ban`; CREATE TABLE `SS13_ban` ( `id` int(11) NOT NULL AUTO_INCREMENT, `bantime` datetime NOT NULL, - `serverip` varchar(32) NOT NULL, - `bantype` varchar(32) NOT NULL, - `reason` text NOT NULL, + `server_ip` int(10) unsigned NOT NULL, + `server_port` smallint(5) unsigned NOT NULL, + `bantype` enum('PERMABAN','TEMPBAN','JOB_PERMABAN','JOB_TEMPBAN','ADMIN_PERMABAN','ADMIN_TEMPBAN') NOT NULL, + `reason` varchar(2048) NOT NULL, `job` varchar(32) DEFAULT NULL, `duration` int(11) NOT NULL, - `rounds` int(11) DEFAULT NULL, `expiration_time` datetime NOT NULL, `ckey` varchar(32) NOT NULL, `computerid` varchar(32) NOT NULL, - `ip` varchar(32) NOT NULL, + `ip` int(10) unsigned NOT NULL, `a_ckey` varchar(32) NOT NULL, `a_computerid` varchar(32) NOT NULL, - `a_ip` varchar(32) NOT NULL, - `who` text NOT NULL, - `adminwho` text NOT NULL, + `a_ip` int(10) unsigned NOT NULL, + `who` varchar(2048) NOT NULL, + `adminwho` varchar(2048) NOT NULL, `edits` text, - `unbanned` int(2) DEFAULT NULL, + `unbanned` tinyint(3) unsigned DEFAULT NULL, `unbanned_datetime` datetime DEFAULT NULL, `unbanned_ckey` varchar(32) DEFAULT NULL, `unbanned_computerid` varchar(32) DEFAULT NULL, - `unbanned_ip` varchar(32) DEFAULT NULL, - PRIMARY KEY (`id`) + `unbanned_ip` int(10) unsigned DEFAULT NULL, + PRIMARY KEY (`id`), + KEY `idx_ban_checkban` (`ckey`,`bantype`,`expiration_time`,`unbanned`,`job`), + KEY `idx_ban_isbanned` (`ckey`,`ip`,`computerid`,`bantype`,`expiration_time`,`unbanned`), + KEY `idx_ban_count` (`id`,`a_ckey`,`bantype`,`expiration_time`,`unbanned`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -116,9 +110,10 @@ DROP TABLE IF EXISTS `SS13_connection_log`; CREATE TABLE `SS13_connection_log` ( `id` int(11) NOT NULL AUTO_INCREMENT, `datetime` datetime DEFAULT NULL, - `serverip` varchar(45) DEFAULT NULL, + `server_ip` int(10) unsigned NOT NULL, + `server_port` smallint(5) unsigned NOT NULL, `ckey` varchar(45) DEFAULT NULL, - `ip` varchar(18) DEFAULT NULL, + `ip` int(10) unsigned NOT NULL, `computerid` varchar(45) DEFAULT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; @@ -133,22 +128,23 @@ DROP TABLE IF EXISTS `SS13_death`; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `SS13_death` ( `id` int(11) NOT NULL AUTO_INCREMENT, - `pod` text NOT NULL COMMENT 'Place of death', - `coord` text NOT NULL COMMENT 'X, Y, Z POD', - `mapname` text NOT NULL, - `server` text NOT NULL, + `pod` varchar(50) NOT NULL, + `coord` varchar(32) NOT NULL, + `mapname` varchar(32) NOT NULL, + `server_ip` int(10) unsigned NOT NULL, + `server_port` smallint(5) unsigned NOT NULL, `tod` datetime NOT NULL COMMENT 'Time of death', - `job` text NOT NULL, - `special` text NOT NULL, - `name` text NOT NULL, - `byondkey` text NOT NULL, - `laname` text NOT NULL COMMENT 'Last attacker name', - `lakey` text NOT NULL COMMENT 'Last attacker key', - `gender` text NOT NULL, - `bruteloss` int(11) NOT NULL, - `brainloss` int(11) NOT NULL, - `fireloss` int(11) NOT NULL, - `oxyloss` int(11) NOT NULL, + `job` varchar(32) NOT NULL, + `special` varchar(32) DEFAULT NULL, + `name` varchar(96) NOT NULL, + `byondkey` varchar(32) NOT NULL, + `laname` varchar(96) DEFAULT NULL, + `lakey` varchar(32) DEFAULT NULL, + `gender` enum('neuter','male','female','plural') NOT NULL, + `bruteloss` smallint(5) unsigned NOT NULL, + `brainloss` smallint(5) unsigned NOT NULL, + `fireloss` smallint(5) unsigned NOT NULL, + `oxyloss` smallint(5) unsigned NOT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -171,6 +167,22 @@ CREATE TABLE `SS13_feedback` ( ) ENGINE=MyISAM DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; +-- +-- Table structure for table `SS13_ipintel` +-- + +DROP TABLE IF EXISTS `SS13_ipintel`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!40101 SET character_set_client = utf8 */; +CREATE TABLE `SS13_ipintel` ( + `ip` int(10) unsigned NOT NULL, + `date` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + `intel` double NOT NULL DEFAULT '0', + PRIMARY KEY (`ip`), + KEY `idx_ipintel` (`ip`,`intel`,`date`) +) ENGINE=InnoDB DEFAULT CHARSET=latin1; +/*!40101 SET character_set_client = @saved_cs_client */; + -- -- Table structure for table `SS13_legacy_population` -- @@ -192,17 +204,49 @@ CREATE TABLE `SS13_legacy_population` ( -- DROP TABLE IF EXISTS `SS13_library`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!40101 SET character_set_client = utf8 */; CREATE TABLE `SS13_library` ( `id` int(11) NOT NULL AUTO_INCREMENT, `author` varchar(45) NOT NULL, `title` varchar(45) NOT NULL, `content` text NOT NULL, - `category` varchar(45) NOT NULL, - `ckey` varchar(45) DEFAULT 'LEGACY', - `datetime` datetime DEFAULT NULL, - `deleted` tinyint(1) DEFAULT NULL, - PRIMARY KEY (`id`) + `category` enum('Any','Fiction','Non-Fiction','Adult','Reference','Religion') NOT NULL, + `ckey` varchar(32) NOT NULL DEFAULT 'LEGACY', + `datetime` datetime NOT NULL, + `deleted` tinyint(1) unsigned DEFAULT NULL, + PRIMARY KEY (`id`), + KEY `deleted_idx` (`deleted`), + KEY `idx_lib_id_del` (`id`,`deleted`), + KEY `idx_lib_del_title` (`deleted`,`title`), + KEY `idx_lib_search` (`deleted`,`author`,`title`,`category`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; +/*!40101 SET character_set_client = @saved_cs_client */; + +-- +-- Table structure for table `SS13_messages` +-- + +DROP TABLE IF EXISTS `SS13_messages`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!40101 SET character_set_client = utf8 */; +CREATE TABLE `SS13_messages` ( + `id` int(11) NOT NULL AUTO_INCREMENT, + `type` enum('memo','message','message sent','note','watchlist entry') NOT NULL, + `targetckey` varchar(32) NOT NULL, + `adminckey` varchar(32) NOT NULL, + `text` varchar(2048) NOT NULL, + `timestamp` datetime NOT NULL, + `server` varchar(32) DEFAULT NULL, + `secret` tinyint(1) unsigned NOT NULL, + `lasteditor` varchar(32) DEFAULT NULL, + `edits` text, + PRIMARY KEY (`id`), + KEY `idx_msg_ckey_time` (`targetckey`,`timestamp`), + KEY `idx_msg_type_ckeys_time` (`type`,`targetckey`,`adminckey`,`timestamp`), + KEY `idx_msg_type_ckey_time_odr` (`type`,`targetckey`,`timestamp`) +) ENGINE=InnoDB DEFAULT CHARSET=latin1; +/*!40101 SET character_set_client = @saved_cs_client */; -- -- Table structure for table `SS13_player` @@ -216,11 +260,13 @@ CREATE TABLE `SS13_player` ( `ckey` varchar(32) NOT NULL, `firstseen` datetime NOT NULL, `lastseen` datetime NOT NULL, - `ip` varchar(18) NOT NULL, + `ip` int(10) unsigned NOT NULL, `computerid` varchar(32) NOT NULL, `lastadminrank` varchar(32) NOT NULL DEFAULT 'Player', PRIMARY KEY (`id`), - UNIQUE KEY `ckey` (`ckey`) + UNIQUE KEY `ckey` (`ckey`), + KEY `idx_player_cid_ckey` (`computerid`,`ckey`), + KEY `idx_player_ip_ckey` (`ip`,`ckey`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -241,7 +287,8 @@ CREATE TABLE `SS13_poll_option` ( `descmin` varchar(32) DEFAULT NULL, `descmid` varchar(32) DEFAULT NULL, `descmax` varchar(32) DEFAULT NULL, - PRIMARY KEY (`id`) + PRIMARY KEY (`id`), + KEY `idx_pop_pollid` (`pollid`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -254,17 +301,20 @@ DROP TABLE IF EXISTS `SS13_poll_question`; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `SS13_poll_question` ( `id` int(11) NOT NULL AUTO_INCREMENT, - `polltype` varchar(16) NOT NULL DEFAULT 'OPTION', + `polltype` enum('OPTION','TEXT','NUMVAL','MULTICHOICE','IRV') NOT NULL, `starttime` datetime NOT NULL, `endtime` datetime NOT NULL, `question` varchar(255) NOT NULL, - `adminonly` tinyint(1) DEFAULT '0', + `adminonly` tinyint(1) unsigned NOT NULL, `multiplechoiceoptions` int(2) DEFAULT NULL, - `createdby_ckey` varchar(45) NULL DEFAULT NULL, - `createdby_ip` varchar(45) NULL DEFAULT NULL, - `for_trialmin` varchar(45) NULL DEFAULT NULL, - `dontshow` tinyint(1) NOT NULL DEFAULT '0', - PRIMARY KEY (`id`) + `createdby_ckey` varchar(32) DEFAULT NULL, + `createdby_ip` varchar(32) DEFAULT NULL, + `for_trialmin` varchar(32) DEFAULT NULL, + `dontshow` tinyint(1) unsigned NOT NULL, + 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_id_time_type_admin` (`id`,`starttime`,`endtime`,`polltype`,`adminonly`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -280,10 +330,11 @@ CREATE TABLE `SS13_poll_textreply` ( `datetime` datetime NOT NULL, `pollid` int(11) NOT NULL, `ckey` varchar(32) NOT NULL, - `ip` varchar(18) NOT NULL, - `replytext` text NOT NULL, + `ip` int(10) unsigned NOT NULL, + `replytext` varchar(2048) NOT NULL, `adminrank` varchar(32) NOT NULL DEFAULT 'Player', - PRIMARY KEY (`id`) + PRIMARY KEY (`id`), + KEY `idx_ptext_pollid_ckey` (`pollid`,`ckey`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; @@ -299,47 +350,21 @@ CREATE TABLE `SS13_poll_vote` ( `datetime` datetime NOT NULL, `pollid` int(11) NOT NULL, `optionid` int(11) NOT NULL, - `ckey` varchar(255) NOT NULL, - `ip` varchar(16) NOT NULL, + `ckey` varchar(32) NOT NULL, + `ip` int(10) unsigned NOT NULL, `adminrank` varchar(32) NOT NULL, `rating` int(2) DEFAULT NULL, - PRIMARY KEY (`id`) + PRIMARY KEY (`id`), + KEY `idx_pvote_pollid_ckey` (`pollid`,`ckey`), + KEY `idx_pvote_optionid_ckey` (`optionid`,`ckey`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; /*!40101 SET character_set_client = @saved_cs_client */; +/*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */; --- --- Table structure for table `SS13_ipintel` --- - -DROP TABLE IF EXISTS `SS13_ipintel`; -/*!40101 SET @saved_cs_client = @@character_set_client */; -/*!40101 SET character_set_client = utf8 */; -CREATE TABLE `SS13_ipintel` ( -`ip` INT UNSIGNED NOT NULL , -`date` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL , -`intel` REAL NOT NULL DEFAULT '0', -PRIMARY KEY ( `ip` ) -) ENGINE = INNODB; -/*!40101 SET character_set_client = @saved_cs_client */; - --- --- Table structure for table `SS13_messages` --- - -DROP TABLE IF EXISTS `SS13_messages`; -/*!40101 SET @saved_cs_client = @@character_set_client */; -/*!40101 SET character_set_client = utf8 */; -CREATE TABLE `SS13_messages` ( - `id` int(11) NOT NULL AUTO_INCREMENT , - `type` varchar(32) NOT NULL , - `targetckey` varchar(32) NOT NULL , - `adminckey` varchar(32) NOT NULL , - `text` text NOT NULL , - `timestamp` datetime NOT NULL , - `server` varchar(32) NULL , - `secret` tinyint(1) NULL DEFAULT 1 , - `lasteditor` varchar(32) NULL , - `edits` text NULL , - PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=latin1; -/*!40101 SET character_set_client = @saved_cs_client */; +/*!40101 SET SQL_MODE=@OLD_SQL_MODE */; +/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */; +/*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */; +/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */; +/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */; +/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */; +/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */; diff --git a/code/modules/admin/DB_ban/functions.dm b/code/modules/admin/DB_ban/functions.dm index 3e35d83715d..a5aead43aff 100644 --- a/code/modules/admin/DB_ban/functions.dm +++ b/code/modules/admin/DB_ban/functions.dm @@ -1,7 +1,7 @@ #define MAX_ADMIN_BANS_PER_ADMIN 1 //Either pass the mob you wish to ban in the 'banned_mob' attribute, or the banckey, banip and bancid variables. If both are passed, the mob takes priority! If a mob is not passed, banckey is the minimum that needs to be passed! banip and bancid are optional. -/datum/admins/proc/DB_ban_record(bantype, mob/banned_mob, duration = -1, reason, job = "", rounds = 0, banckey = null, banip = null, bancid = null) +/datum/admins/proc/DB_ban_record(bantype, mob/banned_mob, duration = -1, reason, job = "", banckey = null, banip = null, bancid = null) if(!check_rights(R_BAN)) return @@ -10,7 +10,6 @@ src << "Failed to establish database connection." return - var/serverip = "[world.internet_address]:[world.port]" var/bantype_pass = 0 var/bantype_str var/maxadminbancheck //Used to limit the number of active bans of a certein type that each admin can give. Used to protect against abuse or mutiny. @@ -121,7 +120,7 @@ usr << "You already logged [MAX_ADMIN_BANS_PER_ADMIN] admin ban(s) or more. Do not abuse this function!" return - var/sql = "INSERT INTO [format_table_name("ban")] (`id`,`bantime`,`serverip`,`bantype`,`reason`,`job`,`duration`,`rounds`,`expiration_time`,`ckey`,`computerid`,`ip`,`a_ckey`,`a_computerid`,`a_ip`,`who`,`adminwho`,`edits`,`unbanned`,`unbanned_datetime`,`unbanned_ckey`,`unbanned_computerid`,`unbanned_ip`) VALUES (null, Now(), '[serverip]', '[bantype_str]', '[reason]', '[job]', [(duration)?"[duration]":"0"], [(rounds)?"[rounds]":"0"], Now() + INTERVAL [(duration>0) ? duration : 0] MINUTE, '[ckey]', '[computerid]', '[ip]', '[a_ckey]', '[a_computerid]', '[a_ip]', '[who]', '[adminwho]', '', null, null, null, null, null)" + var/sql = "INSERT INTO [format_table_name("ban")] (`bantime`,`server_ip`,`server_port`,`bantype`,`reason`,`job`,`duration`,`expiration_time`,`ckey`,`computerid`,`ip`,`a_ckey`,`a_computerid`,`a_ip`,`who`,`adminwho`) VALUES (Now(), INET_ATON('[world.internet_address]'), '[world.port]', '[bantype_str]', '[reason]', '[job]', [(duration)?"[duration]":"0"], Now() + INTERVAL [(duration>0) ? duration : 0] MINUTE, '[ckey]', '[computerid]', INET_ATON('[ip]'), '[a_ckey]', '[a_computerid]', INET_ATON('[a_ip]'), '[who]', '[adminwho]')" var/DBQuery/query_insert = dbcon.NewQuery(sql) query_insert.Execute() usr << "Ban saved to database." @@ -305,7 +304,7 @@ var/unban_computerid = src.owner:computer_id var/unban_ip = src.owner:address - var/sql_update = "UPDATE [format_table_name("ban")] SET unbanned = 1, unbanned_datetime = Now(), unbanned_ckey = '[unban_ckey]', unbanned_computerid = '[unban_computerid]', unbanned_ip = '[unban_ip]' WHERE id = [id]" + var/sql_update = "UPDATE [format_table_name("ban")] SET unbanned = 1, unbanned_datetime = Now(), unbanned_ckey = '[unban_ckey]', unbanned_computerid = '[unban_computerid]', unbanned_ip = INET_ATON('[unban_ip]') WHERE id = [id]" message_admins("[key_name_admin(usr)] has lifted [pckey]'s ban.",1) var/DBQuery/query_update = dbcon.NewQuery(sql_update) diff --git a/code/modules/admin/IsBanned.dm b/code/modules/admin/IsBanned.dm index 7e1b8f038b6..b5e6f8f7b53 100644 --- a/code/modules/admin/IsBanned.dm +++ b/code/modules/admin/IsBanned.dm @@ -69,25 +69,23 @@ var/ipquery = "" var/cidquery = "" if(address) - ipquery = " OR ip = '[address]' " + ipquery = " OR ip = INET_ATON('[address]') " if(computer_id) cidquery = " OR computerid = '[computer_id]' " - var/DBQuery/query = dbcon.NewQuery("SELECT ckey, ip, computerid, a_ckey, reason, expiration_time, duration, bantime, bantype FROM [format_table_name("ban")] WHERE (ckey = '[ckeytext]' [ipquery] [cidquery]) AND (bantype = 'PERMABAN' OR bantype = 'ADMIN_PERMABAN' OR ((bantype = 'TEMPBAN' OR bantype = 'ADMIN_TEMPBAN') AND expiration_time > Now())) AND isnull(unbanned)") + var/DBQuery/query = dbcon.NewQuery("SELECT ckey, a_ckey, reason, expiration_time, duration, bantime, bantype FROM [format_table_name("ban")] WHERE (ckey = '[ckeytext]' [ipquery] [cidquery]) AND (bantype = 'PERMABAN' OR bantype = 'ADMIN_PERMABAN' OR ((bantype = 'TEMPBAN' OR bantype = 'ADMIN_TEMPBAN') AND expiration_time > Now())) AND isnull(unbanned)") query.Execute() while(query.NextRow()) var/pckey = query.item[1] - //var/pip = query.item[2] - //var/pcid = query.item[3] - var/ackey = query.item[4] - var/reason = query.item[5] - var/expiration = query.item[6] - var/duration = query.item[7] - var/bantime = query.item[8] - var/bantype = query.item[9] + var/ackey = query.item[2] + var/reason = query.item[3] + var/expiration = query.item[4] + var/duration = query.item[5] + var/bantime = query.item[6] + var/bantype = query.item[7] if (bantype == "ADMIN_PERMABAN" || bantype == "ADMIN_TEMPBAN") //admin bans MUST match on ckey to prevent cid-spoofing attacks // as well as dynamic ip abuse diff --git a/code/modules/admin/banjob.dm b/code/modules/admin/banjob.dm index 3910310caa7..e824428106a 100644 --- a/code/modules/admin/banjob.dm +++ b/code/modules/admin/banjob.dm @@ -4,7 +4,7 @@ return 0 if(!M.client) //no cache. fallback to a DBQuery - var/DBQuery/query = dbcon.NewQuery("SELECT reason FROM [format_table_name("ban")] WHERE ckey = '[sanitizeSQL(M.ckey)]' AND job = '[sanitizeSQL(rank)]' AND (bantype = 'JOB_PERMABAN' OR (bantype = 'JOB_TEMPBAN' AND expiration_time > Now())) AND isnull(unbanned)") + var/DBQuery/query = dbcon.NewQuery("SELECT reason FROM [format_table_name("ban")] WHERE ckey = '[sanitizeSQL(M.ckey)]' AND (bantype = 'JOB_PERMABAN' OR (bantype = 'JOB_TEMPBAN' AND expiration_time > Now())) AND isnull(unbanned) AND job = '[sanitizeSQL(rank)]'") if(!query.Execute()) log_game("SQL ERROR obtaining jobbans. Error : \[[query.ErrorMsg()]\]\n") return diff --git a/code/modules/admin/topic.dm b/code/modules/admin/topic.dm index 3ed5c8ec9ae..389ed32aff9 100644 --- a/code/modules/admin/topic.dm +++ b/code/modules/admin/topic.dm @@ -249,7 +249,7 @@ else message_admins("Ban process: A mob matching [playermob.ckey] was found at location [playermob.x], [playermob.y], [playermob.z]. Custom ip and computer id fields replaced with the ip and computer id from the located mob.") - if(!DB_ban_record(bantype, playermob, banduration, banreason, banjob, null, banckey, banip, bancid )) + if(!DB_ban_record(bantype, playermob, banduration, banreason, banjob, banckey, banip, bancid )) usr << "Failed to apply ban." return create_message("note", banckey, null, banreason, null, null, 0, 0) diff --git a/code/modules/client/client_procs.dm b/code/modules/client/client_procs.dm index b7984a7fe4c..24065a8a8df 100644 --- a/code/modules/client/client_procs.dm +++ b/code/modules/client/client_procs.dm @@ -351,7 +351,7 @@ var/next_external_rsc = 0 var/sql_ckey = sanitizeSQL(ckey) - var/DBQuery/query_ip = dbcon.NewQuery("SELECT ckey FROM [format_table_name("player")] WHERE ip = '[address]' AND ckey != '[sql_ckey]'") + var/DBQuery/query_ip = dbcon.NewQuery("SELECT ckey FROM [format_table_name("player")] WHERE ip = INET_ATON('[address]') AND ckey != '[sql_ckey]'") query_ip.Execute() related_accounts_ip = "" while(query_ip.NextRow()) @@ -375,12 +375,11 @@ var/next_external_rsc = 0 var/sql_admin_rank = sanitizeSQL(admin_rank) - var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("player")] (id, ckey, firstseen, lastseen, ip, computerid, lastadminrank) VALUES (null, '[sql_ckey]', Now(), Now(), '[sql_ip]', '[sql_computerid]', '[sql_admin_rank]') ON DUPLICATE KEY UPDATE lastseen = VALUES(lastseen), ip = VALUES(ip), computerid = VALUES(computerid), lastadminrank = VALUES(lastadminrank)") + var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("player")] (id, ckey, firstseen, lastseen, ip, computerid, lastadminrank) VALUES (null, '[sql_ckey]', Now(), Now(), INET_ATON('[sql_ip]'), '[sql_computerid]', '[sql_admin_rank]') ON DUPLICATE KEY UPDATE lastseen = VALUES(lastseen), ip = VALUES(ip), computerid = VALUES(computerid), lastadminrank = VALUES(lastadminrank)") query_insert.Execute() //Logging player access - var/serverip = "[world.internet_address]:[world.port]" - var/DBQuery/query_accesslog = dbcon.NewQuery("INSERT INTO `[format_table_name("connection_log")]` (`id`,`datetime`,`serverip`,`ckey`,`ip`,`computerid`) VALUES(null,Now(),'[serverip]','[sql_ckey]','[sql_ip]','[sql_computerid]');") + var/DBQuery/query_accesslog = dbcon.NewQuery("INSERT INTO `[format_table_name("connection_log")]` (`id`,`datetime`,`server_ip`,`server_port`,`ckey`,`ip`,`computerid`) VALUES(null,Now(),INET_ATON('[world.internet_address]'),'[world.port]''[sql_ckey]',INET_ATON('[sql_ip]'),'[sql_computerid]');") query_accesslog.Execute() /client/proc/check_randomizer(topic) diff --git a/code/modules/client/preferences.dm b/code/modules/client/preferences.dm index 3d57d93b0f5..07d8845d108 100644 --- a/code/modules/client/preferences.dm +++ b/code/modules/client/preferences.dm @@ -745,7 +745,7 @@ var/list/preferences_datums = list() if(href_list["jobbancheck"]) var/job = sanitizeSQL(href_list["jobbancheck"]) var/sql_ckey = sanitizeSQL(user.ckey) - var/DBQuery/query_get_jobban = dbcon.NewQuery("SELECT reason, bantime, duration, expiration_time, a_ckey FROM [format_table_name("ban")] WHERE ckey = '[sql_ckey]' AND job = '[job]' AND (bantype = 'JOB_PERMABAN' OR (bantype = 'JOB_TEMPBAN' AND expiration_time > Now())) AND isnull(unbanned)") + var/DBQuery/query_get_jobban = dbcon.NewQuery("SELECT reason, bantime, duration, expiration_time, a_ckey FROM [format_table_name("ban")] WHERE ckey = '[sql_ckey]' AND (bantype = 'JOB_PERMABAN' OR (bantype = 'JOB_TEMPBAN' AND expiration_time > Now())) AND isnull(unbanned) AND job = '[job]'") if(!query_get_jobban.Execute()) var/err = query_get_jobban.ErrorMsg() log_game("SQL ERROR obtaining reason from ban table. Error : \[[err]\]\n") diff --git a/code/modules/mob/new_player/poll.dm b/code/modules/mob/new_player/poll.dm index 1083a9b3543..8d89d64e2cc 100644 --- a/code/modules/mob/new_player/poll.dm +++ b/code/modules/mob/new_player/poll.dm @@ -6,7 +6,7 @@ if(!dbcon.IsConnected()) usr << "Failed to establish database connection." return - var/DBQuery/query_get_poll = dbcon.NewQuery("SELECT id, question FROM [format_table_name("poll_question")] WHERE [(client.holder ? "" : "adminonly = false AND")] Now() BETWEEN starttime AND endtime") + var/DBQuery/query_get_poll = dbcon.NewQuery("SELECT id, question FROM [format_table_name("poll_question")] WHERE Now() BETWEEN starttime AND endtime [(client.holder ? "" : "AND adminonly = false")]") if(!query_get_poll.Execute()) var/err = query_get_poll.ErrorMsg() log_game("SQL ERROR obtaining id, question from poll_question table. Error : \[[err]\]\n") @@ -362,7 +362,7 @@ return . = "Player" if(client.holder) - . = client.holder.rank + . = client.holder.rank.name return . @@ -386,17 +386,7 @@ if (!pollid || pollid < 0) return 0 //validate the poll is actually the right type of poll and its still active - var/DBQuery/select_query = dbcon.NewQuery({" - SELECT id - FROM [format_table_name("poll_question")] - WHERE - [(holder ? "" : "adminonly = false AND")] - id = [pollid] - AND - Now() BETWEEN starttime AND endtime - AND - polltype = '[type]' - "}) + var/DBQuery/select_query = dbcon.NewQuery("SELECT id FROM [format_table_name("poll_question")] WHERE id = [pollid] AND Now() BETWEEN starttime AND endtime AND polltype = '[type]' [(holder ? "" : "AND adminonly = false")]") if (!select_query.Execute()) var/err = select_query.ErrorMsg() log_game("SQL ERROR validating poll via poll_question table. Error : \[[err]\]\n") @@ -422,7 +412,7 @@ var/datum/admins/holder = client.holder var/rank = "Player" if (holder) - rank = holder.rank + rank = holder.rank.name var/ckey = client.ckey var/address = client.address @@ -461,7 +451,7 @@ for (var/vote in numberedvotelist) if (sqlrowlist != "") sqlrowlist += ", " //a comma (,) at the start of the first row to insert will trigger a SQL error - sqlrowlist += "(Now(), [pollid], [vote], '[sanitizeSQL(ckey)]', '[sanitizeSQL(address)]', '[sanitizeSQL(rank)]')" + sqlrowlist += "(Now(), [pollid], [vote], '[sanitizeSQL(ckey)]', INET_ATON('[sanitizeSQL(address)]'), '[sanitizeSQL(rank)]')" //now lets delete their old votes (if any) var/DBQuery/voted_query = dbcon.NewQuery("DELETE FROM [format_table_name("poll_vote")] WHERE pollid = [pollid] AND ckey = '[ckey]'") @@ -492,10 +482,10 @@ //validate the poll if (!vote_valid_check(pollid, client.holder, POLLTYPE_OPTION)) return 0 - var/adminrank = poll_check_voted(pollid) + var/adminrank = sanitizeSQL(poll_check_voted(pollid)) if(!adminrank) return - var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("poll_vote")] (datetime, pollid, optionid, ckey, ip, adminrank) VALUES (Now(), [pollid], [optionid], '[ckey]', '[client.address]', '[adminrank]')") + var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("poll_vote")] (datetime, pollid, optionid, ckey, ip, adminrank) VALUES (Now(), [pollid], [optionid], '[ckey]', INET_ATON('[client.address]'), '[adminrank]')") if(!query_insert.Execute()) var/err = query_insert.ErrorMsg() log_game("SQL ERROR adding vote to table. Error : \[[err]\]\n") @@ -517,14 +507,14 @@ if(!replytext) usr << "The text you entered was blank. Please correct the text and submit again." return - var/adminrank = poll_check_voted(pollid, TRUE) + var/adminrank = sanitizeSQL(poll_check_voted(pollid, TRUE)) if(!adminrank) return replytext = sanitizeSQL(replytext) if(!(length(replytext) > 0) || !(length(replytext) <= 8000)) usr << "The text you entered was invalid or too long. Please correct the text and submit again." return - var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("poll_textreply")] (datetime ,pollid ,ckey ,ip ,replytext ,adminrank) VALUES (Now(), [pollid], '[ckey]', '[client.address]', '[replytext]', '[adminrank]')") + var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("poll_textreply")] (datetime ,pollid ,ckey ,ip ,replytext ,adminrank) VALUES (Now(), [pollid], '[ckey]', INET_ATON('[client.address]'), '[replytext]', '[adminrank]')") if(!query_insert.Execute()) var/err = query_insert.ErrorMsg() log_game("SQL ERROR adding text reply to table. Error : \[[err]\]\n") @@ -553,8 +543,9 @@ return var/adminrank = "Player" if(client.holder) - adminrank = client.holder.rank - var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("poll_vote")] (datetime ,pollid ,optionid ,ckey ,ip ,adminrank, rating) VALUES (Now(), [pollid], [optionid], '[ckey]', '[client.address]', '[adminrank]', [(isnull(rating)) ? "null" : rating])") + adminrank = client.holder.rank.name + adminrank = sanitizeSQL(adminrank) + var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("poll_vote")] (datetime ,pollid ,optionid ,ckey ,ip ,adminrank, rating) VALUES (Now(), [pollid], [optionid], '[ckey]', INET_ATON('[client.address]'), '[adminrank]', [(isnull(rating)) ? "null" : rating])") if(!query_insert.Execute()) var/err = query_insert.ErrorMsg() log_game("SQL ERROR adding vote to table. Error : \[[err]\]\n") @@ -595,11 +586,12 @@ return 2 var/adminrank = "Player" if(client.holder) - adminrank = client.holder.rank - var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("poll_vote")] (datetime, pollid, optionid, ckey, ip, adminrank) VALUES (Now(), [pollid], [optionid], '[ckey]', '[client.address]', '[adminrank]')") + adminrank = client.holder.rank.name + adminrank = sanitizeSQL(adminrank) + var/DBQuery/query_insert = dbcon.NewQuery("INSERT INTO [format_table_name("poll_vote")] (datetime, pollid, optionid, ckey, ip, adminrank) VALUES (Now(), [pollid], [optionid], '[ckey]', INET_ATON('[client.address]'), '[adminrank]')") if(!query_insert.Execute()) var/err = query_insert.ErrorMsg() log_game("SQL ERROR adding vote to table. Error : \[[err]\]\n") return 1 usr << browse(null,"window=playerpoll") - return 0 \ No newline at end of file + return 0 diff --git a/code/orphaned_procs/statistics.dm b/code/orphaned_procs/statistics.dm index 58a473138d7..b8eccb06e26 100644 --- a/code/orphaned_procs/statistics.dm +++ b/code/orphaned_procs/statistics.dm @@ -269,11 +269,10 @@ var/datum/feedback/blackbox = new() var/sqltime = time2text(world.realtime, "YYYY-MM-DD hh:mm:ss") var/coord = "[L.x], [L.y], [L.z]" var/map = MAP_NAME - var/server = "[world.internet_address]:[world.port]" if(!dbcon.Connect()) log_game("SQL ERROR during death reporting. Failed to connect.") else - var/DBQuery/query = dbcon.NewQuery("INSERT INTO [format_table_name("death")] (name, byondkey, job, special, pod, tod, laname, lakey, gender, bruteloss, fireloss, brainloss, oxyloss, coord, mapname, server) VALUES ('[sqlname]', '[sqlkey]', '[sqljob]', '[sqlspecial]', '[sqlpod]', '[sqltime]', '[laname]', '[lakey]', '[L.gender]', [L.getBruteLoss()], [L.getFireLoss()], [L.brainloss], [L.getOxyLoss()], '[coord]', '[map]', '[server]')") + var/DBQuery/query = dbcon.NewQuery("INSERT INTO [format_table_name("death")] (name, byondkey, job, special, pod, tod, laname, lakey, gender, bruteloss, fireloss, brainloss, oxyloss, coord, mapname, server_ip, server_port) VALUES ('[sqlname]', '[sqlkey]', '[sqljob]', '[sqlspecial]', '[sqlpod]', '[sqltime]', '[laname]', '[lakey]', '[L.gender]', [L.getBruteLoss()], [L.getFireLoss()], [L.brainloss], [L.getOxyLoss()], '[coord]', '[map]', INET_ATON('[world.internet_address]'), '[world.port]')") if(!query.Execute()) var/err = query.ErrorMsg() log_game("SQL ERROR during death reporting. Error : \[[err]\]\n")