diff --git a/database/new/mysql.sql b/database/new/mysql.sql index 8cd93a2..5d6100c 100644 --- a/database/new/mysql.sql +++ b/database/new/mysql.sql @@ -36,21 +36,6 @@ CREATE TABLE IF NOT EXISTS `alias` ( CONSTRAINT `alias_player` FOREIGN KEY (`player_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION ) ENGINE=InnoDB DEFAULT CHARSET=latin1; -CREATE TABLE IF NOT EXISTS `player_level` ( - `id` int(10) unsigned NOT NULL AUTO_INCREMENT, - `player_id` int(10) unsigned NOT NULL, - `invoker_id` int(10) unsigned NOT NULL, - `level_id` int(11) NOT NULL, - `datetime` int(10) unsigned NOT NULL, - PRIMARY KEY (`id`), - KEY `player_level_player_idx` (`player_id`), - KEY `player_level_invoker_idx` (`invoker_id`), - KEY `player_level_level_idx` (`level_id`), - CONSTRAINT `player_level_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - CONSTRAINT `player_level_level` FOREIGN KEY (`level_id`) REFERENCES `level` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - CONSTRAINT `player_level_player` FOREIGN KEY (`player_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION -) ENGINE=InnoDB DEFAULT CHARSET=latin1; - CREATE TABLE IF NOT EXISTS `history` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `victim_id` int(10) unsigned NOT NULL, diff --git a/database/new/sqlite.sql b/database/new/sqlite.sql index cc4b51c..fdd0101 100644 --- a/database/new/sqlite.sql +++ b/database/new/sqlite.sql @@ -32,20 +32,6 @@ CREATE TABLE IF NOT EXISTS `alias` ( CREATE INDEX IF NOT EXISTS `alias_player_idx` ON `alias` (`player_id`); -CREATE TABLE IF NOT EXISTS `player_level` ( - `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, - `player_id` INTEGER NOT NULL, - `invoker_id` INTEGER NOT NULL, - `level_id` INTEGER NOT NULL, - `datetime` INTEGER NOT NULL, - CONSTRAINT `level_player` FOREIGN KEY (`player_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - CONSTRAINT `level_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION - CONSTRAINT `level_level` FOREIGN KEY (`level_id`) REFERENCES `level` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION -); - -CREATE INDEX IF NOT EXISTS `level_player_idx` ON `player_level` (`player_id`); -CREATE INDEX IF NOT EXISTS `level_invoker_idx` ON `player_level` (`invoker_id`); - CREATE TABLE IF NOT EXISTS `history` ( `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, `victim_id` INTEGER NOT NULL, diff --git a/database/upgrade/1.1.0/mysql.sql b/database/upgrade/1.1.0/mysql.sql index 2386b80..60ba8f7 100644 --- a/database/upgrade/1.1.0/mysql.sql +++ b/database/upgrade/1.1.0/mysql.sql @@ -1,44 +1,50 @@ --- rename level table to player_level --- now we're at it, also update the columns -ALTER TABLE `level` - DROP FOREIGN KEY `level_player`, - DROP FOREIGN KEY `level_admin`; -ALTER TABLE `level` +-- rename warns to history +ALTER TABLE `warn` + DROP FOREIGN KEY `warn_player`, + DROP FOREIGN KEY `warn_admin`; +ALTER TABLE `warn` DROP INDEX `admin_idx`, DROP INDEX `player_idx`; -ALTER TABLE `level` - CHANGE COLUMN `admin_id` `invoker_id` INT(10) UNSIGNED NOT NULL AFTER `player_id`, - CHANGE COLUMN `level` `level_id` INT(11) NOT NULL, - RENAME TO `player_level`; +ALTER TABLE `warn` + CHANGE COLUMN `reason` `reason` VARCHAR(128) NOT NULL AFTER `datetime`, + CHANGE COLUMN `player_id` `victim_id` INT(10) UNSIGNED NOT NULL, + CHANGE COLUMN `admin_id` `invoker_id` INT(10) UNSIGNED NOT NULL, + ADD COLUMN `type` VARCHAR(16) NOT NULL AFTER `invoker_id`, + ADD INDEX `history_victim_idx` (`victim_id` ASC), + ADD INDEX `history_invoker_idx` (`invoker_id` ASC), + RENAME TO `history`; -ALTER TABLE `player_level` - ADD INDEX `player_level_player_idx` (`player_id` ASC), - ADD INDEX `player_level_invoker_idx` (`invoker_id` ASC); -ALTER TABLE `player_level` - ADD CONSTRAINT `player_level_player` - FOREIGN KEY (`player_id`) +ALTER TABLE `history` + ADD CONSTRAINT `history_victim` + FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - ADD CONSTRAINT `player_level_invoker` + ADD CONSTRAINT `history_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION; +UPDATE `history` SET `type`='warn' WHERE `type` IS NULL; + +INSERT INTO `history` (`id`, `victim_id`, `invoker_id`, `type`, `datetime`, `reason`) SELECT `id`, `player_id`, `admin_id`, 'level' AS `type`, `datetime`, `level` FROM `level`; + +DROP TABLE `level`; + -- create acl tables CREATE TABLE IF NOT EXISTS `level` ( - `id` int(11) NOT NULL, - `name` varchar(64) DEFAULT NULL, - PRIMARY KEY (`id`) + `id` int(11) NOT NULL, + `name` varchar(64) DEFAULT NULL, + PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1; CREATE TABLE IF NOT EXISTS `level_role` ( - `level_id` int(11) NOT NULL, - `role` varchar(32) NOT NULL, - PRIMARY KEY (`level_id`,`role`), - CONSTRAINT `level_role_level` FOREIGN KEY (`level_id`) REFERENCES `level` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION + `level_id` int(11) NOT NULL, + `role` varchar(32) NOT NULL, + PRIMARY KEY (`level_id`,`role`), + CONSTRAINT `level_role_level` FOREIGN KEY (`level_id`) REFERENCES `level` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION ) ENGINE=InnoDB DEFAULT CHARSET=latin1; -- populate acl @@ -266,16 +272,6 @@ INSERT INTO `level_role`(`level_id`, `role`) VALUES (5, 'silentcmds'); INSERT INTO `level_role`(`level_id`, `role`) VALUES (5, 'spy'); --- add player_level level FK constraint -ALTER TABLE `player_level` - ADD INDEX `player_level_level_idx` (`level_id` ASC); -ALTER TABLE `player_level` - ADD CONSTRAINT `player_level_level` - FOREIGN KEY (`level_id`) - REFERENCES `level` (`id`) - ON DELETE NO ACTION - ON UPDATE NO ACTION; - -- update player table ALTER TABLE `player` ADD COLUMN `level_id` INT NOT NULL AFTER `ip`, @@ -296,63 +292,34 @@ UPDATE `player` SET `level_id`=5 WHERE `guid`='XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX' UPDATE `player` SET `lastseen`=(SELECT MAX(`lastused`) AS `lastused` FROM `alias` AS `a` WHERE `a`.`player_id`=`player`.`id`); UPDATE `player` SET `seen`=(SELECT SUM(`used`) AS `used` FROM `alias` AS `a` WHERE `a`.`player_id`=`player`.`id`); --- rename warns to history -ALTER TABLE `warn` - DROP FOREIGN KEY `warn_player`, - DROP FOREIGN KEY `warn_admin`; -ALTER TABLE `warn` - DROP INDEX `admin_idx`, - DROP INDEX `player_idx`; - -ALTER TABLE `warn` - CHANGE COLUMN `reason` `reason` VARCHAR(128) NOT NULL AFTER `datetime`, - CHANGE COLUMN `player_id` `victim_id` INT(10) UNSIGNED NOT NULL, - CHANGE COLUMN `admin_id` `invoker_id` INT(10) UNSIGNED NOT NULL, - ADD COLUMN `type` VARCHAR(16) NOT NULL AFTER `invoker_id`, - ADD INDEX `history_victim_idx` (`victim_id` ASC), - ADD INDEX `history_invoker_idx` (`invoker_id` ASC), - RENAME TO `history`; - -ALTER TABLE `history` - ADD CONSTRAINT `history_victim` - FOREIGN KEY (`victim_id`) - REFERENCES `player` (`id`) - ON DELETE NO ACTION - ON UPDATE NO ACTION, - ADD CONSTRAINT `history_invoker` - FOREIGN KEY (`invoker_id`) - REFERENCES `player` (`id`) - ON DELETE NO ACTION - ON UPDATE NO ACTION; - -- create mute and ban tables CREATE TABLE IF NOT EXISTS `mute` ( - `id` int(10) unsigned NOT NULL AUTO_INCREMENT, - `victim_id` int(10) unsigned NOT NULL, - `invoker_id` int(10) unsigned NOT NULL, - `type` smallint(5) unsigned NOT NULL, - `issued` int(10) unsigned NOT NULL, - `expires` int(10) unsigned NOT NULL, - `duration` int(10) unsigned NOT NULL, - `reason` varchar(128) CHARACTER SET utf8 NOT NULL, - PRIMARY KEY (`id`), - KEY `mute_victim_idx` (`victim_id`), - KEY `mute_invoker_idx` (`invoker_id`), - CONSTRAINT `mute_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - CONSTRAINT `mute_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION + `id` int(10) unsigned NOT NULL AUTO_INCREMENT, + `victim_id` int(10) unsigned NOT NULL, + `invoker_id` int(10) unsigned NOT NULL, + `type` smallint(5) unsigned NOT NULL, + `issued` int(10) unsigned NOT NULL, + `expires` int(10) unsigned NOT NULL, + `duration` int(10) unsigned NOT NULL, + `reason` varchar(128) CHARACTER SET utf8 NOT NULL, + PRIMARY KEY (`id`), + KEY `mute_victim_idx` (`victim_id`), + KEY `mute_invoker_idx` (`invoker_id`), + CONSTRAINT `mute_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, + CONSTRAINT `mute_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci; CREATE TABLE IF NOT EXISTS `ban` ( - `id` int(10) unsigned NOT NULL AUTO_INCREMENT, - `victim_id` int(10) unsigned DEFAULT NULL, - `invoker_id` int(10) unsigned NOT NULL, - `issued` int(10) unsigned NOT NULL, - `expires` int(10) unsigned NOT NULL, - `duration` int(10) unsigned NOT NULL, - `reason` varchar(128) CHARACTER SET utf8 NOT NULL, - PRIMARY KEY (`id`), - KEY `ban_victim_idx` (`victim_id`), - KEY `ban_invoker_idx` (`invoker_id`), - CONSTRAINT `ban_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - CONSTRAINT `ban_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION + `id` int(10) unsigned NOT NULL AUTO_INCREMENT, + `victim_id` int(10) unsigned DEFAULT NULL, + `invoker_id` int(10) unsigned NOT NULL, + `issued` int(10) unsigned NOT NULL, + `expires` int(10) unsigned NOT NULL, + `duration` int(10) unsigned NOT NULL, + `reason` varchar(128) CHARACTER SET utf8 NOT NULL, + PRIMARY KEY (`id`), + KEY `ban_victim_idx` (`victim_id`), + KEY `ban_invoker_idx` (`invoker_id`), + CONSTRAINT `ban_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, + CONSTRAINT `ban_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci; diff --git a/database/upgrade/1.1.0/sqlite.sql b/database/upgrade/1.1.0/sqlite.sql index 8a3c545..945820f 100644 --- a/database/upgrade/1.1.0/sqlite.sql +++ b/database/upgrade/1.1.0/sqlite.sql @@ -1,20 +1,23 @@ --- rename level table to player_level --- now we're at it, also update the columns -CREATE TABLE IF NOT EXISTS `player_level` ( +-- rename warns to history +CREATE TABLE IF NOT EXISTS `history` ( `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, - `player_id` INTEGER NOT NULL, + `victim_id` INTEGER NOT NULL, `invoker_id` INTEGER NOT NULL, - `level_id` INTEGER NOT NULL, + `type` TEXT NOT NULL, `datetime` INTEGER NOT NULL, - CONSTRAINT `level_player` FOREIGN KEY (`player_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - CONSTRAINT `level_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION - CONSTRAINT `level_level` FOREIGN KEY (`level_id`) REFERENCES `level` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION + `reason` TEXT NOT NULL, + CONSTRAINT `history_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, + CONSTRAINT `history_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION ); -CREATE INDEX IF NOT EXISTS `level_player_idx` ON `player_level` (`player_id`); -CREATE INDEX IF NOT EXISTS `level_invoker_idx` ON `player_level` (`invoker_id`); +CREATE INDEX IF NOT EXISTS `history_victim_idx` ON `history` (`victim_id`); +CREATE INDEX IF NOT EXISTS `history_invoker_idx` ON `history` (`invoker_id`); -INSERT INTO `player_level` (`id`, `player_id`, `invoker_id`, `level_id`, `datetime`) SELECT `id`, `player_id`, `admin_id`, `level`, `datetime` FROM `level`; +INSERT INTO `history` (`id`, `victim_id`, `invoker_id`, `type`, `datetime`, `reason`) SELECT `id`, `player_id`, `admin_id`, 'warn' AS `type`, `datetime`, `reason` FROM `warn`; + +DROP TABLE `warn`; + +INSERT INTO `history` (`id`, `victim_id`, `invoker_id`, `type`, `datetime`, `reason`) SELECT `id`, `player_id`, `admin_id`, 'level' AS `type`, `datetime`, `level` FROM `level`; DROP TABLE `level`; @@ -272,13 +275,13 @@ COMMIT; -- update player table CREATE TABLE IF NOT EXISTS `player_x` ( - `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, - `guid` TEXT NOT NULL UNIQUE, - `ip` TEXT NOT NULL, - `level_id` INTEGER NOT NULL, - `lastseen` INTEGER NOT NULL, - `seen` INTEGER NOT NULL, - CONSTRAINT `player_level` FOREIGN KEY (`level_id`) REFERENCES `level` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION + `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + `guid` TEXT NOT NULL UNIQUE, + `ip` TEXT NOT NULL, + `level_id` INTEGER NOT NULL, + `lastseen` INTEGER NOT NULL, + `seen` INTEGER NOT NULL, + CONSTRAINT `player_level` FOREIGN KEY (`level_id`) REFERENCES `level` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION ); INSERT INTO `player_x` (`id`, `guid`, `ip`, `level_id`, `lastseen`, `seen`) SELECT `id`, `guid`, `ip`, 0 AS `level_id`, 0 AS `lastseen`, 0 AS `seen` FROM `player`; @@ -294,52 +297,33 @@ UPDATE `player` SET `level_id`=5 WHERE `guid`='XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX' UPDATE `player` SET `lastseen`=(SELECT MAX(`lastused`) AS `lastused` FROM `alias` AS `a` WHERE `a`.`player_id`=`player`.`id`); UPDATE `player` SET `seen`=(SELECT SUM(`used`) AS `used` FROM `alias` AS `a` WHERE `a`.`player_id`=`player`.`id`); --- rename warns to history -CREATE TABLE IF NOT EXISTS `history` ( - `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, - `victim_id` INTEGER NOT NULL, - `invoker_id` INTEGER NOT NULL, - `type` TEXT NOT NULL, - `datetime` INTEGER NOT NULL, - `reason` TEXT NOT NULL, - CONSTRAINT `history_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - CONSTRAINT `history_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION -); - -CREATE INDEX IF NOT EXISTS `history_victim_idx` ON `history` (`victim_id`); -CREATE INDEX IF NOT EXISTS `history_invoker_idx` ON `history` (`invoker_id`); - -INSERT INTO `history` (`id`, `victim_id`, `invoker_id`, `type`, `datetime`, `reason`) SELECT `id`, `player_id`, `admin_id`, 'warn' AS `type`, `datetime`, `reason` FROM `warn`; - -DROP TABLE `warn`; - -- create mute and ban tables CREATE TABLE IF NOT EXISTS `mute` ( - `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, - `victim_id` INTEGER NOT NULL, - `invoker_id` INTEGER NOT NULL, - `type` TEXT NOT NULL, - `issued` INTEGER NOT NULL, - `expires` INTEGER NOT NULL, - `duration` INTEGER NOT NULL, - `reason` TEXT NOT NULL, - CONSTRAINT `mute_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - CONSTRAINT `mute_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION + `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + `victim_id` INTEGER NOT NULL, + `invoker_id` INTEGER NOT NULL, + `type` TEXT NOT NULL, + `issued` INTEGER NOT NULL, + `expires` INTEGER NOT NULL, + `duration` INTEGER NOT NULL, + `reason` TEXT NOT NULL, + CONSTRAINT `mute_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, + CONSTRAINT `mute_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION ); CREATE INDEX IF NOT EXISTS `mute_victim_idx` ON `mute` (`victim_id`); CREATE INDEX IF NOT EXISTS `mute_invoker_idx` ON `mute` (`invoker_id`); CREATE TABLE IF NOT EXISTS `ban` ( - `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, - `victim_id` INTEGER NOT NULL, - `invoker_id` INTEGER NOT NULL, - `issued` INTEGER NOT NULL, - `expires` INTEGER NOT NULL, - `duration` INTEGER NOT NULL, - `reason` TEXT NOT NULL, - CONSTRAINT `ban_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, - CONSTRAINT `ban_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION + `id` INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + `victim_id` INTEGER NOT NULL, + `invoker_id` INTEGER NOT NULL, + `issued` INTEGER NOT NULL, + `expires` INTEGER NOT NULL, + `duration` INTEGER NOT NULL, + `reason` TEXT NOT NULL, + CONSTRAINT `ban_victim` FOREIGN KEY (`victim_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION, + CONSTRAINT `ban_invoker` FOREIGN KEY (`invoker_id`) REFERENCES `player` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION ); CREATE INDEX IF NOT EXISTS `ban_victim_idx` ON `ban` (`victim_id`);