Commit 66634c9b authored by ctrlaltca's avatar ctrlaltca
Browse files

Merge pull request #1808 from ctrlaltca/innodb

Move schema to Innodb and add FKs
parents 108ec145 aac2d09f
-- Servatrice db migration from version 12 to version 13
-- WARNING: this is quite a big change, so you really, REALLY should
-- backup your database before attempting to execute this migration.
-- First move all the tables to the InnoDB engine
ALTER TABLE `cockatrice_schema_version` ENGINE=InnoDB;
ALTER TABLE `cockatrice_decklist_files` ENGINE=InnoDB;
ALTER TABLE `cockatrice_decklist_folders` ENGINE=InnoDB;
ALTER TABLE `cockatrice_games` ENGINE=InnoDB;
ALTER TABLE `cockatrice_games_players` ENGINE=InnoDB;
ALTER TABLE `cockatrice_news` ENGINE=InnoDB;
ALTER TABLE `cockatrice_users` ENGINE=InnoDB;
ALTER TABLE `cockatrice_uptime` ENGINE=InnoDB;
ALTER TABLE `cockatrice_servermessages` ENGINE=InnoDB;
ALTER TABLE `cockatrice_ignorelist` ENGINE=InnoDB;
ALTER TABLE `cockatrice_buddylist` ENGINE=InnoDB;
ALTER TABLE `cockatrice_bans` ENGINE=InnoDB;
ALTER TABLE `cockatrice_warnings` ENGINE=InnoDB;
ALTER TABLE `cockatrice_sessions` ENGINE=InnoDB;
ALTER TABLE `cockatrice_servers` ENGINE=InnoDB;
ALTER TABLE `cockatrice_replays` ENGINE=InnoDB;
ALTER TABLE `cockatrice_replays_access` ENGINE=InnoDB;
ALTER TABLE `cockatrice_rooms` ENGINE=InnoDB;
ALTER TABLE `cockatrice_rooms_gametypes` ENGINE=InnoDB;
ALTER TABLE `cockatrice_log` ENGINE=InnoDB;
ALTER TABLE `cockatrice_activation_emails` ENGINE=InnoDB;
ALTER TABLE `cockatrice_user_analytics` ENGINE=InnoDB;
-- Fix the replays tables not using unsigned values for id_game and id_player
ALTER TABLE `cockatrice_replays` MODIFY COLUMN `id_game` int(7) unsigned NULL;
ALTER TABLE `cockatrice_replays_access` MODIFY COLUMN `id_game` int(7) unsigned NOT NULL;
ALTER TABLE `cockatrice_replays_access` MODIFY COLUMN `id_player` int(7) unsigned NOT NULL;
-- Now add some foreign keys between tables. Since there was no constaint before,
-- we need to ensure no leftover record (eg. a user deck without an user) exists
-- before adding the FK, or the query will fail.
DELETE FROM `cockatrice_decklist_files` WHERE `id_user` NOT IN (SELECT `id` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_decklist_files` ADD FOREIGN KEY(`id_user`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_decklist_folders` WHERE `id_user` NOT IN (SELECT `id` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_decklist_folders` ADD FOREIGN KEY(`id_user`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_news` WHERE `id_user` NOT IN (SELECT `id` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_news` ADD FOREIGN KEY(`id_user`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_ignorelist` WHERE `id_user1` NOT IN (SELECT `id` FROM `cockatrice_users`);
DELETE FROM `cockatrice_ignorelist` WHERE `id_user2` NOT IN (SELECT `id` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_ignorelist` ADD FOREIGN KEY(`id_user1`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
ALTER TABLE `cockatrice_ignorelist` ADD FOREIGN KEY(`id_user2`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_buddylist` WHERE `id_user1` NOT IN (SELECT `id` FROM `cockatrice_users`);
DELETE FROM `cockatrice_buddylist` WHERE `id_user2` NOT IN (SELECT `id` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_buddylist` ADD FOREIGN KEY(`id_user1`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
ALTER TABLE `cockatrice_buddylist` ADD FOREIGN KEY(`id_user2`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_user_analytics` WHERE `id` NOT IN (SELECT `id` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_user_analytics` ADD FOREIGN KEY(`id`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_log` WHERE `sender_id` NOT IN (SELECT `id` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_log` ADD FOREIGN KEY(`sender_id`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_activation_emails` WHERE `name` NOT IN (SELECT `name` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_activation_emails` ADD FOREIGN KEY(`name`) REFERENCES `cockatrice_users`(`name`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_rooms_gametypes` WHERE `id_room` NOT IN (SELECT `id` FROM `cockatrice_rooms`);
ALTER TABLE `cockatrice_rooms_gametypes` ADD FOREIGN KEY(`id_room`) REFERENCES `cockatrice_rooms`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_games_players` WHERE `id_game` NOT IN (SELECT `id` FROM `cockatrice_games`);
ALTER TABLE `cockatrice_games_players` ADD FOREIGN KEY(`id_game`) REFERENCES `cockatrice_games`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_replays` WHERE `id_game` NOT IN (SELECT `id` FROM `cockatrice_games`);
ALTER TABLE `cockatrice_replays` ADD FOREIGN KEY(`id_game`) REFERENCES `cockatrice_games`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_replays_access` WHERE `id_game` NOT IN (SELECT `id` FROM `cockatrice_games`);
ALTER TABLE `cockatrice_replays_access` ADD FOREIGN KEY(`id_game`) REFERENCES `cockatrice_games`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_replays_access` WHERE `id_player` NOT IN (SELECT `id` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_replays_access` ADD FOREIGN KEY(`id_player`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
DELETE FROM `cockatrice_bans` WHERE `id_admin` NOT IN (SELECT `id` FROM `cockatrice_users`);
ALTER TABLE `cockatrice_bans` ADD FOREIGN KEY(`id_admin`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE;
-- Last: update schema version
UPDATE cockatrice_schema_version SET version=13 WHERE version=12;
......@@ -5,5 +5,3 @@ DBNAME="servatrice" #set this to the database name used
TABLEPREFIX="cockatrice" #set this to the prefix used for the table names in the database (do not inclue the _)
SQLCONFFILE="./mysql.cnf" #set this to the path that contains the mysql.cnf file
mysql --defaults-file=$SQLCONFFILE -h localhost -e 'delete from servatrice.cockatrice_games where time_finished < DATE_SUB(now(), INTERVAL 8 DAY)'
\ No newline at end of file
mysql --defaults-file=$SQLCONFFILE -h localhost -e 'delete from servatrice.cockatrice_replays where id_game NOT IN (select id from servatrice.cockatrice_games)'
mysql --defaults-file=$SQLCONFFILE -h localhost -e 'delete from servatrice.cockatrice_replays_access where id_game NOT IN (select id from servatrice.cockatrice_games)'
......@@ -18,9 +18,30 @@ SET SQL_MODE="NO_AUTO_VALUE_ON_ZERO";
CREATE TABLE IF NOT EXISTS `cockatrice_schema_version` (
`version` int(7) unsigned NOT NULL,
PRIMARY KEY (`version`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
) ENGINE=INNODB DEFAULT CHARSET=utf8;
INSERT INTO cockatrice_schema_version VALUES(12);
INSERT INTO cockatrice_schema_version VALUES(13);
-- users and user data tables
CREATE TABLE IF NOT EXISTS `cockatrice_users` (
`id` int(7) unsigned zerofill NOT NULL auto_increment,
`admin` tinyint(1) NOT NULL,
`name` varchar(35) NOT NULL,
`realname` varchar(255) NOT NULL,
`gender` char(1) NOT NULL,
`password_sha512` char(120) NOT NULL,
`email` varchar(255) NOT NULL,
`country` char(2) NOT NULL,
`avatar_bmp` blob NOT NULL,
`registrationDate` datetime NOT NULL,
`active` tinyint(1) NOT NULL,
`token` binary(16),
`clientid` varchar(15) NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `name` (`name`),
KEY `token` (`token`),
KEY `email` (`email`)
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_decklist_files` (
`id` int(7) unsigned zerofill NOT NULL auto_increment,
......@@ -30,8 +51,9 @@ CREATE TABLE IF NOT EXISTS `cockatrice_decklist_files` (
`upload_time` datetime NOT NULL,
`content` text NOT NULL,
PRIMARY KEY (`id`),
KEY `FolderPlusUser` (`id_folder`,`id_user`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
KEY `FolderPlusUser` (`id_folder`,`id_user`),
FOREIGN KEY(`id_user`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_decklist_folders` (
`id` int(7) unsigned zerofill NOT NULL auto_increment,
......@@ -39,9 +61,45 @@ CREATE TABLE IF NOT EXISTS `cockatrice_decklist_folders` (
`id_user` int(7) unsigned NULL,
`name` varchar(30) NOT NULL,
PRIMARY KEY (`id`),
KEY `ParentPlusUser` (`id_parent`,`id_user`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
KEY `ParentPlusUser` (`id_parent`,`id_user`),
FOREIGN KEY(`id_user`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_ignorelist` (
`id_user1` int(7) unsigned NOT NULL,
`id_user2` int(7) unsigned NOT NULL,
UNIQUE KEY `key` (`id_user1`, `id_user2`),
FOREIGN KEY(`id_user1`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY(`id_user2`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_buddylist` (
`id_user1` int(7) unsigned NOT NULL,
`id_user2` int(7) unsigned NOT NULL,
UNIQUE KEY `key` (`id_user1`, `id_user2`),
FOREIGN KEY(`id_user1`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY(`id_user2`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
-- rooms
CREATE TABLE IF NOT EXISTS `cockatrice_rooms` (
`id` int(7) unsigned NOT NULL auto_increment,
`name` varchar(50) NOT NULL,
`descr` varchar(255) NOT NULL,
`permissionlevel` varchar(20) NOT NULL,
`auto_join` tinyint(1) default 0,
`join_message` varchar(255) NOT NULL,
`chat_history_size` int(4) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_rooms_gametypes` (
`id_room` int(7) unsigned NOT NULL,
`name` varchar(50) NOT NULL,
FOREIGN KEY(`id_room`) REFERENCES `cockatrice_rooms`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
-- games
CREATE TABLE IF NOT EXISTS `cockatrice_games` (
`room_name` varchar(255) NOT NULL,
`id` int(7) unsigned NOT NULL auto_increment,
......@@ -53,42 +111,58 @@ CREATE TABLE IF NOT EXISTS `cockatrice_games` (
`time_started` datetime default NULL,
`time_finished` datetime default NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_games_players` (
`id_game` int(7) unsigned zerofill NOT NULL,
`player_name` varchar(255) NOT NULL,
KEY `id_game` (`id_game`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
FOREIGN KEY(`id_game`) REFERENCES `cockatrice_games`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
-- Note: an empty row with id_game = NULL is created when the game is created,
-- and then updated when the game ends with the full replay data.
CREATE TABLE IF NOT EXISTS `cockatrice_replays` (
`id` int(7) NOT NULL AUTO_INCREMENT,
`id_game` int(7) unsigned NULL,
`duration` int(7) NOT NULL,
`replay` mediumblob NOT NULL,
PRIMARY KEY (`id`),
FOREIGN KEY(`id_game`) REFERENCES `cockatrice_games`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_replays_access` (
`id_game` int(7) unsigned NOT NULL,
`id_player` int(7) unsigned NOT NULL,
`replay_name` varchar(255) COLLATE utf8_unicode_ci NOT NULL,
`do_not_hide` tinyint(1) NOT NULL,
KEY `id_player` (`id_player`),
FOREIGN KEY(`id_game`) REFERENCES `cockatrice_games`(`id`) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY(`id_player`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
-- server administration
-- Note: unused table
CREATE TABLE IF NOT EXISTS `cockatrice_news` (
`id` int(7) unsigned zerofill NOT NULL auto_increment,
`id_user` int(7) unsigned zerofill NOT NULL,
`news_date` datetime NOT NULL,
`subject` varchar(255) NOT NULL,
`content` text NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_users` (
`id` int(7) unsigned zerofill NOT NULL auto_increment,
`admin` tinyint(1) NOT NULL,
`name` varchar(35) NOT NULL,
`realname` varchar(255) NOT NULL,
`gender` char(1) NOT NULL,
`password_sha512` char(120) NOT NULL,
`email` varchar(255) NOT NULL,
`country` char(2) NOT NULL,
`avatar_bmp` blob NOT NULL,
`registrationDate` datetime NOT NULL,
`active` tinyint(1) NOT NULL,
`token` binary(16),
`clientid` varchar(15) NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `name` (`name`),
KEY `token` (`token`),
KEY `email` (`email`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
FOREIGN KEY(`id_user`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
-- Note: unused table
CREATE TABLE IF NOT EXISTS `cockatrice_servers` (
`id` mediumint(8) unsigned NOT NULL,
`ssl_cert` text COLLATE utf8_unicode_ci NOT NULL,
`hostname` varchar(255) COLLATE utf8_unicode_ci NOT NULL,
`address` varchar(255) COLLATE utf8_unicode_ci NOT NULL,
`game_port` mediumint(8) unsigned NOT NULL,
`control_port` mediumint(9) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_uptime` (
`id_server` tinyint(3) NOT NULL,
......@@ -99,31 +173,28 @@ CREATE TABLE IF NOT EXISTS `cockatrice_uptime` (
`rx_bytes` int(11) NOT NULL,
`tx_bytes` int(11) NOT NULL,
PRIMARY KEY (`timest`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_servermessages` (
`id_server` tinyint(3) not null default 0,
`timest` datetime NOT NULL default '0000-00-00 00:00:00',
`message` text,
PRIMARY KEY (`timest`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_ignorelist` (
`id_user1` int(7) unsigned NOT NULL,
`id_user2` int(7) unsigned NOT NULL,
UNIQUE KEY `key` (`id_user1`, `id_user2`),
KEY `id_user1` (`id_user1`),
KEY `id_user2` (`id_user2`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_buddylist` (
`id_user1` int(7) unsigned NOT NULL,
`id_user2` int(7) unsigned NOT NULL,
UNIQUE KEY `key` (`id_user1`, `id_user2`),
KEY `id_user1` (`id_user1`),
KEY `id_user2` (`id_user2`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_sessions` (
`id` int(9) NOT NULL AUTO_INCREMENT,
`user_name` varchar(255) COLLATE utf8_unicode_ci NOT NULL,
`id_server` tinyint(3) NOT NULL,
`ip_address` char(15) COLLATE utf8_unicode_ci NOT NULL,
`start_time` datetime NOT NULL,
`end_time` datetime DEFAULT NULL,
`clientid` varchar(15) NOT NULL,
PRIMARY KEY (`id`),
KEY `username` (`user_name`)
) ENGINE=INNODB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
-- server moderation
CREATE TABLE IF NOT EXISTS `cockatrice_bans` (
`user_name` varchar(255) NOT NULL,
`ip_address` varchar(255) NOT NULL,
......@@ -135,8 +206,9 @@ CREATE TABLE IF NOT EXISTS `cockatrice_bans` (
`clientid` varchar(15) NOT NULL,
PRIMARY KEY (`user_name`,`time_from`),
KEY `time_from` (`time_from`,`ip_address`),
KEY `ip_address` (`ip_address`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
KEY `ip_address` (`ip_address`),
FOREIGN KEY(`id_admin`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_warnings` (
`user_id` int(7) unsigned NOT NULL,
......@@ -146,64 +218,7 @@ CREATE TABLE IF NOT EXISTS `cockatrice_warnings` (
`time_of` datetime NOT NULL,
`clientid` varchar(15) NOT NULL,
PRIMARY KEY (`user_id`,`time_of`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_sessions` (
`id` int(9) NOT NULL AUTO_INCREMENT,
`user_name` varchar(255) COLLATE utf8_unicode_ci NOT NULL,
`id_server` tinyint(3) NOT NULL,
`ip_address` char(15) COLLATE utf8_unicode_ci NOT NULL,
`start_time` datetime NOT NULL,
`end_time` datetime DEFAULT NULL,
`clientid` varchar(15) NOT NULL,
PRIMARY KEY (`id`),
KEY `username` (`user_name`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
CREATE TABLE IF NOT EXISTS `cockatrice_servers` (
`id` mediumint(8) unsigned NOT NULL,
`ssl_cert` text COLLATE utf8_unicode_ci NOT NULL,
`hostname` varchar(255) COLLATE utf8_unicode_ci NOT NULL,
`address` varchar(255) COLLATE utf8_unicode_ci NOT NULL,
`game_port` mediumint(8) unsigned NOT NULL,
`control_port` mediumint(9) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_replays` (
`id` int(7) NOT NULL AUTO_INCREMENT,
`id_game` int(7) NOT NULL,
`duration` int(7) NOT NULL,
`replay` mediumblob NOT NULL,
PRIMARY KEY (`id`),
KEY `id_game` (`id_game`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_replays_access` (
`id_game` int(7) NOT NULL,
`id_player` int(7) NOT NULL,
`replay_name` varchar(255) COLLATE utf8_unicode_ci NOT NULL,
`do_not_hide` tinyint(1) NOT NULL,
KEY `id_player` (`id_player`),
KEY `id_game` (`id_game`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_rooms` (
`id` int(7) unsigned NOT NULL auto_increment,
`name` varchar(50) NOT NULL,
`descr` varchar(255) NOT NULL,
`permissionlevel` varchar(20) NOT NULL,
`auto_join` tinyint(1) default 0,
`join_message` varchar(255) NOT NULL,
`chat_history_size` int(4) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_rooms_gametypes` (
`id_room` int(7) unsigned NOT NULL,
`name` varchar(50) NOT NULL,
KEY (`id_room`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_log` (
`log_time` datetime NOT NULL,
......@@ -218,17 +233,21 @@ CREATE TABLE IF NOT EXISTS `cockatrice_log` (
KEY `sender_ip` (`sender_ip`),
KEY `target_type` (`target_type`),
KEY `target_id` (`target_id`),
KEY `target_name` (`target_name`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
KEY `target_name` (`target_name`),
FOREIGN KEY(`sender_id`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
-- No FK on target_id, it can be zero
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_activation_emails` (
`name` varchar(35) NOT NULL
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
`name` varchar(35) NOT NULL,
FOREIGN KEY(`name`) REFERENCES `cockatrice_users`(`name`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
CREATE TABLE IF NOT EXISTS `cockatrice_user_analytics` (
`id` int(7) unsigned zerofill NOT NULL,
`client_ver` varchar(35) NOT NULL,
`last_login` datetime NOT NULL,
`notes` varchar(255) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
PRIMARY KEY (`id`),
FOREIGN KEY(`id`) REFERENCES `cockatrice_users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=INNODB DEFAULT CHARSET=utf8;
......@@ -675,7 +675,7 @@ int Servatrice_DatabaseInterface::getNextReplayId()
if (!checkSql())
return -1;
QSqlQuery *query = prepareQuery("insert into {prefix}_replays () values ()");
QSqlQuery *query = prepareQuery("insert into {prefix}_replays (id_game) values (NULL)");
execSqlQuery(query);
return query->lastInsertId().toInt();
......@@ -1013,7 +1013,7 @@ QList<ServerInfo_ChatMessage> Servatrice_DatabaseInterface::getMessageLogHistory
return results;
// BUILD QUERY STRING BASED ON PASSED IN VALUES
QString queryString = "SELECT * FROM cockatrice_log WHERE `sender_ip` IS NOT NULL";
QString queryString = "SELECT * FROM {prefix}_log WHERE `sender_ip` IS NOT NULL";
if (!user.isEmpty())
queryString.append(" AND (`sender_name` = :user_name OR `target_name` = :user_name)");
......
......@@ -9,7 +9,7 @@
#include "server.h"
#include "server_database_interface.h"
#define DATABASE_SCHEMA_VERSION 12
#define DATABASE_SCHEMA_VERSION 13
class Servatrice;
......
Supports Markdown
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment