Skip to content

Commit

Permalink
Properly add the metric_data, subsystem_metrics, `subsystem_extra…
Browse files Browse the repository at this point in the history
…_metrics`, `overwatch_whitelist`, and `overwatch_asn_ban` tables to the database schema. (Monkestation#3486)
  • Loading branch information
Absolucy authored Sep 20, 2024
1 parent 7f24d34 commit 45cea4c
Show file tree
Hide file tree
Showing 3 changed files with 154 additions and 4 deletions.
70 changes: 67 additions & 3 deletions SQL/database_changelog.md
Original file line number Diff line number Diff line change
Expand Up @@ -2,19 +2,83 @@ Any time you make a change to the schema files, remember to increment the databa

Make sure to also update `DB_MAJOR_VERSION` and `DB_MINOR_VERSION`, which can be found in `code/__DEFINES/subsystem.dm`.

The latest database version is 5.24; The query to update the schema revision table is:
The latest database version is 5.26; The query to update the schema revision table is:

```sql
INSERT INTO `schema_revision` (`major`, `minor`) VALUES (5, 25);
INSERT INTO `schema_revision` (`major`, `minor`) VALUES (5, 26);
```
or

```sql
INSERT INTO `SS13_schema_revision` (`major`, `minor`) VALUES (5, 25);
INSERT INTO `SS13_schema_revision` (`major`, `minor`) VALUES (5, 26);
```

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

-----------------------------------------------------
Version 5.26, 20 September 2024, by Absolucy
Properly added the previously undocumented `metric_data`, `subsystem_metrics`, `subsystem_extra_metrics`, `overwatch_whitelist`, and `overwatch_asn_ban` tables.
```sql
CREATE TABLE `metric_data` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`datetime` datetime NOT NULL,
`cpu` decimal(20,10) unsigned DEFAULT NULL,
`maptick` decimal(20,10) unsigned DEFAULT NULL,
`elapsed_processed` int(15) unsigned DEFAULT NULL,
`elapsed_real` int(15) unsigned DEFAULT NULL,
`client_count` int(15) unsigned DEFAULT NULL,
`round_id` int(15) unsigned DEFAULT NULL,
`relational_id` varchar(255) DEFAULT NULL,
PRIMARY KEY (`id`) USING BTREE
) ENGINE=MyISAM DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;

CREATE TABLE `overwatch_asn_ban` (
`ip` varchar(21) NOT NULL,
`asn` varchar(100) NOT NULL,
`a_ckey` varchar(30) NOT NULL,
`timestamp` datetime NOT NULL,
PRIMARY KEY (`asn`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;

CREATE TABLE `overwatch_ip_cache` (
`ip` varchar(50) NOT NULL DEFAULT '',
`response` longtext NOT NULL,
PRIMARY KEY (`ip`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;

CREATE TABLE `overwatch_whitelist` (
`ckey` varchar(30) NOT NULL,
`a_ckey` varchar(30) NOT NULL,
`timestamp` datetime NOT NULL,
PRIMARY KEY (`ckey`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;

CREATE TABLE `subsystem_extra_metrics` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`datetime` datetime NOT NULL,
`round_id` int(15) unsigned DEFAULT NULL,
`ss_id` varchar(255) DEFAULT NULL,
`relation_id_SS` varchar(255) DEFAULT NULL,
`ss_value` longtext CHARACTER SET utf8mb4 COLLATE utf8mb4_bin NOT NULL,
PRIMARY KEY (`id`) USING BTREE,
CONSTRAINT `ss_value` CHECK (json_valid(`ss_value`))
) ENGINE=MyISAM DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;

CREATE TABLE `subsystem_metrics` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`avg_iter_count` decimal(20,6) NOT NULL DEFAULT 0.000000,
`avg_drift` decimal(20,6) NOT NULL DEFAULT 0.000000,
`datetime` datetime NOT NULL,
`round_id` int(15) unsigned DEFAULT NULL,
`ss_id` varchar(255) DEFAULT NULL,
`relational_id` varchar(255) DEFAULT NULL,
`relation_id_SS` varchar(255) DEFAULT NULL,
`cost` decimal(20,6) unsigned DEFAULT NULL,
`tick_usage` decimal(20,6) unsigned DEFAULT NULL,
PRIMARY KEY (`id`) USING BTREE
) ENGINE=MyISAM DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
```

-----------------------------------------------------
Version 5.25, 8 September 2024, by Absolucy
Added `log_directory` field to the `round` table.
Expand Down
86 changes: 86 additions & 0 deletions SQL/tgstation_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -708,6 +708,9 @@ CREATE TABLE `telemetry_connections` (
UNIQUE INDEX `unique_constraints` (`ckey` , `telemetry_ckey` , `address` , `computer_id`)
);

--
-- Table structure for table `tutorial_completions`
--
DROP TABLE IF EXISTS `tutorial_completions`;
CREATE TABLE `tutorial_completions` (
`id` INT NOT NULL AUTO_INCREMENT,
Expand All @@ -716,6 +719,89 @@ CREATE TABLE `tutorial_completions` (
PRIMARY KEY (`id`),
UNIQUE INDEX `ckey_tutorial_unique` (`ckey`, `tutorial_key`));

--
-- Table structure for table `metric_data`
--
DROP TABLE IF EXISTS `metric_data`;
CREATE TABLE `metric_data` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`datetime` datetime NOT NULL,
`cpu` decimal(20,10) unsigned DEFAULT NULL,
`maptick` decimal(20,10) unsigned DEFAULT NULL,
`elapsed_processed` int(15) unsigned DEFAULT NULL,
`elapsed_real` int(15) unsigned DEFAULT NULL,
`client_count` int(15) unsigned DEFAULT NULL,
`round_id` int(15) unsigned DEFAULT NULL,
`relational_id` varchar(255) DEFAULT NULL,
PRIMARY KEY (`id`) USING BTREE
) ENGINE=MyISAM DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;

--
-- Table structure for table `overwatch_asn_ban`
--
DROP TABLE IF EXISTS `overwatch_asn_ban`;
CREATE TABLE `overwatch_asn_ban` (
`ip` varchar(21) NOT NULL,
`asn` varchar(100) NOT NULL,
`a_ckey` varchar(30) NOT NULL,
`timestamp` datetime NOT NULL,
PRIMARY KEY (`asn`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;

--
-- Table structure for table `overwatch_ip_cache`
--
DROP TABLE IF EXISTS `overwatch_ip_cache`;
CREATE TABLE `overwatch_ip_cache` (
`ip` varchar(50) NOT NULL DEFAULT '',
`response` longtext NOT NULL,
PRIMARY KEY (`ip`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;

--
-- Table structure for table `overwatch_whitelist`
--
DROP TABLE IF EXISTS `overwatch_whitelist`;
CREATE TABLE `overwatch_whitelist` (
`ckey` varchar(30) NOT NULL,
`a_ckey` varchar(30) NOT NULL,
`timestamp` datetime NOT NULL,
PRIMARY KEY (`ckey`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;

--
-- Table structure for table `subsystem_extra_metrics`
--
DROP TABLE IF EXISTS `subsystem_extra_metrics`;
CREATE TABLE `subsystem_extra_metrics` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`datetime` datetime NOT NULL,
`round_id` int(15) unsigned DEFAULT NULL,
`ss_id` varchar(255) DEFAULT NULL,
`relation_id_SS` varchar(255) DEFAULT NULL,
`ss_value` longtext CHARACTER SET utf8mb4 COLLATE utf8mb4_bin NOT NULL,
PRIMARY KEY (`id`) USING BTREE,
CONSTRAINT `ss_value` CHECK (json_valid(`ss_value`))
) ENGINE=MyISAM DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;

--
-- Table structure for table `metric_data`
--
DROP TABLE IF EXISTS `subsystem_metrics`;
CREATE TABLE `subsystem_metrics` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`avg_iter_count` decimal(20,6) NOT NULL DEFAULT 0.000000,
`avg_drift` decimal(20,6) NOT NULL DEFAULT 0.000000,
`datetime` datetime NOT NULL,
`round_id` int(15) unsigned DEFAULT NULL,
`ss_id` varchar(255) DEFAULT NULL,
`relational_id` varchar(255) DEFAULT NULL,
`relation_id_SS` varchar(255) DEFAULT NULL,
`cost` decimal(20,6) unsigned DEFAULT NULL,
`tick_usage` decimal(20,6) unsigned DEFAULT NULL,
PRIMARY KEY (`id`) USING BTREE
) ENGINE=MyISAM DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;

/*!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
2 changes: 1 addition & 1 deletion code/__DEFINES/subsystems.dm
Original file line number Diff line number Diff line change
Expand Up @@ -20,7 +20,7 @@
*
* make sure you add an update to the schema_version stable in the db changelog
*/
#define DB_MINOR_VERSION 25
#define DB_MINOR_VERSION 26 // monkestation edit: we've added plenty of our own tables to the db


//! ## Timing subsystem
Expand Down

0 comments on commit 45cea4c

Please sign in to comment.