diff --git a/prepare_dev_environment.sh b/prepare_dev_environment.sh index da76ef61..68bf663b 100755 --- a/prepare_dev_environment.sh +++ b/prepare_dev_environment.sh @@ -2,7 +2,7 @@ #We're not auto-detecting DB updates because if we do any schema changes in production, we'll have to remove them from patch-schema.sql when we download the updated archive, months later #FILENAME=`curl --silent https://ifarchive.org/if-archive/info/ifdb/ | grep --only-matching "ifdb-archive-\d*.zip" | tail -1` -FILENAME=ifdb-archive-20240901.zip +FILENAME=ifdb-archive-20241201.zip if [ ! -f sql/$FILENAME ]; then curl -o sql/$FILENAME https://ifarchive.org/if-archive/info/ifdb/$FILENAME fi diff --git a/sql/create-db.sql b/sql/create-db.sql index 6ba6f353..ef4e5e75 100644 --- a/sql/create-db.sql +++ b/sql/create-db.sql @@ -1,4 +1,4 @@ -CREATE DATABASE IF NOT EXISTS ifdb CHARACTER SET latin1 COLLATE latin1_german2_ci; +CREATE DATABASE IF NOT EXISTS ifdb CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE USER IF NOT EXISTS ifdb; USE ifdb; diff --git a/sql/incoming-schema-changes.sql b/sql/incoming-schema-changes.sql index a14be3c8..aaaa18ed 100644 --- a/sql/incoming-schema-changes.sql +++ b/sql/incoming-schema-changes.sql @@ -2,225 +2,3 @@ USE ifdb; -- use this script for pending changes to the production DB schema - -CREATE TABLE `blockedtagsynonyms` ( - `blockedtagsynonymid` bigint(20) unsigned NOT NULL AUTO_INCREMENT, - `blockedtag` varchar(255) COLLATE latin1_german2_ci NOT NULL, - `preferredtag` varchar(255) COLLATE latin1_german2_ci NOT NULL, - PRIMARY KEY (`blockedtagsynonymid`), - UNIQUE KEY `blockedtag` (`blockedtag`) -) ENGINE = MyISAM DEFAULT CHARSET = latin1 COLLATE = latin1_german2_ci; - -insert into blockedtagsynonyms (blockedtag, preferredtag) -values ('sci-fi', 'science fiction'); - - -ALTER TABLE `stylesheets` ADD COLUMN `dark` tinyint(1) NOT NULL DEFAULT 0; - -update stylesheets set contents = '@import url("/ifdb.css");', dark = 1, modified = now() where stylesheetid = 5; - -ALTER DATABASE `ifdb` CHARACTER SET = utf8mb4 COLLATE = utf8mb4_unicode_ci; -ALTER TABLE `audit` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `blockedtagsynonyms` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `compdivs` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `competitions` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `compgames` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `compprofilelinks` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `comps_history` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `crossrecs` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `downloadhelp` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `extreviews` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `filetypes` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `formatprivs` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `gamefwds` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `gamelinks` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `gameprofilelinks` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `gameRatingsSandbox0_mv` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `games_history` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `games` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `gametags` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `gamexrefs` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `gamexreftypes` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `ifids` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `iso639` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `iso639x` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `logins` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `mirrors` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `news` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `nonces` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `operatingsystems` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `osprivs` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `osversions` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `persistentsessions` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `playedgames` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `pollcomments` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `polls` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `pollvotes` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `privileges` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `reclistitems` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `reclists` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `reviewflags` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `reviews` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `reviewtags` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `reviewvotes` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `sitenews` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `specialreviewers` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `stylepics` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `stylesheets` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `tagstats` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `ucomments` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `unwishlists` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `userfilters` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `users` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `userScores_mv` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; -ALTER TABLE `wishlists` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; - - --- --- Table structure for table `playertimes` --- - -DROP TABLE IF EXISTS `playertimes`; -CREATE TABLE playertimes ( - id INT AUTO_INCREMENT, - gameid VARCHAR(32) NOT NULL, - userid VARCHAR(32) NOT NULL, - time_in_minutes INT(5) unsigned not null, - time_note VARCHAR(150), - createdate DATETIME DEFAULT now(), - PRIMARY KEY (id), - UNIQUE KEY `game_user` (`gameid`, `userid`) -); - --- Sample time values for The Tempest (by Grigg) -insert into playertimes (gameid, userid, time_in_minutes) -values ('59g5czw7izz7aoip', 'kaw2cas7dyiq2tmg', 63); - -insert into playertimes (gameid, userid, time_in_minutes, time_note) -values ('59g5czw7izz7aoip', '0000000000000000', 128, 'Used a few hints'); - -insert into playertimes (gameid, userid, time_in_minutes) -values ('59g5czw7izz7aoip', '0000000000000001', 55); - - -insert into playertimes (gameid, userid, time_in_minutes) -values ('59g5czw7izz7aoip', 'pwamtkqtbeyc8eyn', 37); - -insert into playertimes (gameid, userid, time_in_minutes) -values ('59g5czw7izz7aoip', '6cfekbbjqeduww77', 76); - --- Sample time values for Ninja (by Panks) -insert into playertimes (gameid, userid, time_in_minutes) -values ('n93jonigjmva9e3g', 'kaw2cas7dyiq2tmg', 139); - -insert into playertimes (gameid, userid, time_in_minutes) -values ('n93jonigjmva9e3g', '0000000000000001', 134); - -insert into playertimes (gameid, userid, time_in_minutes) -values ('n93jonigjmva9e3g', '0000000000000000', 204); - -insert into playertimes (gameid, userid, time_in_minutes, time_note) -values ('n93jonigjmva9e3g', 'pwamtkqtbeyc8eyn', 116, 'Solved in story mode.'); - --- Sample time values for Four Seconds (by Reigstad) -insert into playertimes (gameid, userid, time_in_minutes) -values ('bu6mmul5vxci5vqc', 'kaw2cas7dyiq2tmg', 1); - -insert into playertimes (gameid, userid, time_in_minutes, time_note) -values ('bu6mmul5vxci5vqc', 'pwamtkqtbeyc8eyn', 6, 'without hints'); - - - --- The roundMedianTime function takes the exact median time in minutes --- and rounds it. If the time is over an hour, round to the nearest 5 minutes. --- Otherwise, round to the nearest minute. - -DELIMITER $$ - -CREATE FUNCTION roundMedianTime( - exact_median_in_minutes DECIMAL(6, 1) -) -RETURNS INT(5) -DETERMINISTIC -BEGIN - DECLARE rounded_median_in_minutes INT(5); - IF exact_median_in_minutes > 60 THEN - SET rounded_median_in_minutes = (round(exact_median_in_minutes/5))*5; - ELSE - SET rounded_median_in_minutes = round(exact_median_in_minutes); - END IF; - RETURN (rounded_median_in_minutes); -END $$ - -DELIMITER ; - - --- View to calculate the estimated play time (the rounded median time) of each game -CREATE VIEW `gametimes` AS - SELECT - DISTINCT gameid, - roundMedianTime( median(time_in_minutes) OVER (PARTITION BY gameid) ) as `rounded_median_time_in_minutes` - FROM playertimes; - - --- Create a materialized view to store the data from the gametimes view -CREATE TABLE gametimes_mv ( - gameid VARCHAR(32) NOT NULL, - rounded_median_time_in_minutes INT(5) unsigned not null, - PRIMARY KEY (gameid), - KEY (rounded_median_time_in_minutes) -); - - - --- Populate the gametimes_mv materialized view from the gametimes view -lock tables gametimes_mv write, gametimes read; -truncate table gametimes_mv; -insert into gametimes_mv select * from gametimes; -unlock tables; - - --- Procedure to update one row of the gametimes_mv materialized view -DROP PROCEDURE IF EXISTS refresh_gametimes_mv; -DELIMITER $$ - -CREATE PROCEDURE refresh_gametimes_mv ( - IN new_gameid varchar(32) COLLATE latin1_german2_ci -) -BEGIN -select * -from gametimes -where gameid = new_gameid -into @gameid, - @rounded_median_time_in_minutes; -if @gameid is null then - delete from gametimes_mv where gameid = new_gameid; -else -insert into gametimes_mv -values ( - @gameid, - @rounded_median_time_in_minutes - ) on duplicate key -update gameid = @gameid, - rounded_median_time_in_minutes = @rounded_median_time_in_minutes; -END IF; -END; -$$ - -DELIMITER ; - - --- Create triggers so that when an individual player time in the playertimes table is --- updated, the rounded median time for that game (in the gametimes_mv materialized view) --- will also be updated. -CREATE TRIGGER playertime_insert -AFTER INSERT ON playertimes FOR EACH ROW -call refresh_gametimes_mv(NEW.gameid); - -CREATE TRIGGER playertime_update -AFTER UPDATE ON playertimes FOR EACH ROW -call refresh_gametimes_mv(NEW.gameid); - -CREATE TRIGGER playertime_delete -AFTER DELETE ON playertimes FOR EACH ROW -call refresh_gametimes_mv(OLD.gameid); diff --git a/sql/unscrub-ifarchive.sql b/sql/unscrub-ifarchive.sql index 3b5df18f..2ec69a89 100644 --- a/sql/unscrub-ifarchive.sql +++ b/sql/unscrub-ifarchive.sql @@ -4,44 +4,44 @@ DROP TABLE IF EXISTS `audit`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `audit` ( - `userid` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', + `userid` varchar(32) NOT NULL DEFAULT '', `ts` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, - `action` mediumtext COLLATE latin1_german2_ci NOT NULL -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; + `action` mediumtext NOT NULL +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; DROP TABLE IF EXISTS `userfilters`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `userfilters` ( - `userid` char(32) COLLATE latin1_german2_ci NOT NULL, - `targetuserid` char(32) COLLATE latin1_german2_ci NOT NULL, - `filtertype` char(1) COLLATE latin1_german2_ci NOT NULL, + `userid` char(32) NOT NULL, + `targetuserid` char(32) NOT NULL, + `filtertype` char(1) NOT NULL, KEY `userid` (`userid`), KEY `targetuserid` (`targetuserid`) -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; ALTER TABLE `users` - ADD COLUMN `email` varchar(255) COLLATE latin1_german2_ci NOT NULL DEFAULT '', + ADD COLUMN `email` varchar(255) NOT NULL DEFAULT '', ADD COLUMN `emailflags` tinyint(2) NOT NULL DEFAULT '3', - ADD COLUMN `profilestatus` varchar(1) COLLATE latin1_german2_ci DEFAULT NULL, + ADD COLUMN `profilestatus` varchar(1) DEFAULT NULL, ADD COLUMN `password` varchar(40) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL DEFAULT '', - ADD COLUMN `pswsalt` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', - ADD COLUMN `activationcode` varchar(40) COLLATE latin1_german2_ci DEFAULT NULL, - ADD COLUMN `acctstatus` char(1) COLLATE latin1_german2_ci NOT NULL DEFAULT 'A', + ADD COLUMN `pswsalt` varchar(32) NOT NULL DEFAULT '', + ADD COLUMN `activationcode` varchar(40) DEFAULT NULL, + ADD COLUMN `acctstatus` char(1) NOT NULL DEFAULT 'A', ADD COLUMN `lastlogin` datetime DEFAULT NULL, - ADD COLUMN `privileges` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '''''', + ADD COLUMN `privileges` varchar(32) NOT NULL DEFAULT '''''', ADD COLUMN `defaultos` int(11) unsigned DEFAULT NULL, ADD COLUMN `defaultosvsn` int(11) unsigned DEFAULT NULL, ADD COLUMN `noexedownloads` tinyint(1) NOT NULL DEFAULT '0', - ADD COLUMN `publiclists` varchar(10) COLLATE latin1_german2_ci DEFAULT NULL, + ADD COLUMN `publiclists` varchar(10) DEFAULT NULL, ADD COLUMN `mirrorid` int(11) unsigned NOT NULL DEFAULT '100', ADD COLUMN `stylesheetid` bigint(20) DEFAULT NULL, - ADD COLUMN `offsite_display` char(1) COLLATE latin1_german2_ci NOT NULL DEFAULT 'A', + ADD COLUMN `offsite_display` char(1) NOT NULL DEFAULT 'A', ADD COLUMN `accessibility` tinyint(1) DEFAULT NULL, ADD COLUMN `caughtupdate` datetime DEFAULT NULL, - ADD COLUMN `remarks` mediumtext COLLATE latin1_german2_ci, + ADD COLUMN `remarks` mediumtext, ADD COLUMN `tosversion` int(11) NOT NULL DEFAULT '1', ADD COLUMN `Sandbox` int(11) NOT NULL DEFAULT '0', ADD KEY `email` (`email`) @@ -56,8 +56,8 @@ DROP TABLE IF EXISTS `formatprivs`; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `formatprivs` ( `fmtid` int(11) unsigned NOT NULL DEFAULT '0', - `userid` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '' -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; + `userid` varchar(32) NOT NULL DEFAULT '' +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -68,12 +68,12 @@ DROP TABLE IF EXISTS `logins`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `logins` ( - `uid` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', - `ip` varchar(16) COLLATE latin1_german2_ci NOT NULL DEFAULT '', + `uid` varchar(32) NOT NULL DEFAULT '', + `ip` varchar(16) NOT NULL DEFAULT '', `when` datetime NOT NULL, KEY `uid` (`uid`), KEY `ip` (`ip`) -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -84,11 +84,11 @@ DROP TABLE IF EXISTS `nonces`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `nonces` ( - `nonceid` varchar(256) COLLATE latin1_german2_ci NOT NULL, - `hash` varchar(40) COLLATE latin1_german2_ci NOT NULL, + `nonceid` varchar(256) NOT NULL, + `hash` varchar(40) NOT NULL, `created` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, KEY `nonceid` (`nonceid`) -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -100,8 +100,8 @@ DROP TABLE IF EXISTS `osprivs`; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `osprivs` ( `osid` int(11) unsigned NOT NULL DEFAULT '0', - `userid` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '' -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; + `userid` varchar(32) NOT NULL DEFAULT '' +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -112,12 +112,12 @@ DROP TABLE IF EXISTS `persistentsessions`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `persistentsessions` ( - `id` varchar(64) COLLATE latin1_german2_ci NOT NULL DEFAULT '', - `userid` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', + `id` varchar(64) NOT NULL DEFAULT '', + `userid` varchar(32) NOT NULL DEFAULT '', `lastlogin` datetime NOT NULL, PRIMARY KEY (`id`), KEY `userid` (`userid`) -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -128,9 +128,9 @@ DROP TABLE IF EXISTS `privileges`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `privileges` ( - `code` char(1) COLLATE latin1_german2_ci NOT NULL DEFAULT '', - `name` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '' -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; + `code` char(1) NOT NULL DEFAULT '', + `name` varchar(32) NOT NULL DEFAULT '' +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -142,17 +142,17 @@ DROP TABLE IF EXISTS `reviewflags`; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `reviewflags` ( `reviewid` bigint(20) NOT NULL, - `flagger` varchar(32) COLLATE latin1_german2_ci NOT NULL, - `flagtype` char(1) COLLATE latin1_german2_ci NOT NULL, - `notes` mediumtext COLLATE latin1_german2_ci, + `flagger` varchar(32) NOT NULL, + `flagtype` char(1) NOT NULL, + `notes` mediumtext, `created` datetime NOT NULL, KEY `reviewid` (`reviewid`), KEY `flagger` (`flagger`) -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; ALTER TABLE `reviewvotes` - ADD COLUMN `userid` char(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', + ADD COLUMN `userid` char(32) NOT NULL DEFAULT '', ADD KEY `userid` (`userid`) ; @@ -164,17 +164,17 @@ DROP TABLE IF EXISTS `stylepics`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `stylepics` ( - `userid` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', - `name` varchar(128) COLLATE latin1_german2_ci NOT NULL DEFAULT '', - `picture` varchar(64) COLLATE latin1_german2_ci NOT NULL DEFAULT '', - `desc` mediumtext COLLATE latin1_german2_ci, + `userid` varchar(32) NOT NULL DEFAULT '', + `name` varchar(128) NOT NULL DEFAULT '', + `picture` varchar(64) NOT NULL DEFAULT '', + `desc` mediumtext, `picturebytes` int(11) DEFAULT NULL, PRIMARY KEY (`userid`,`name`) -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; ALTER TABLE `ucomments` - ADD COLUMN `private` varchar(32) COLLATE latin1_german2_ci DEFAULT NULL + ADD COLUMN `private` varchar(32) DEFAULT NULL ; -- @@ -201,12 +201,12 @@ DROP TABLE IF EXISTS `userfilters`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `userfilters` ( - `userid` char(32) COLLATE latin1_german2_ci NOT NULL, - `targetuserid` char(32) COLLATE latin1_german2_ci NOT NULL, - `filtertype` char(1) COLLATE latin1_german2_ci NOT NULL, + `userid` char(32) NOT NULL, + `targetuserid` char(32) NOT NULL, + `filtertype` char(1) NOT NULL, KEY `userid` (`userid`), KEY `targetuserid` (`targetuserid`) -) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; +) ENGINE=MyISAM; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -846,7 +846,7 @@ where ifnull((now() > `reviews`.`embargodate`), 1) drop table if exists userScores_mv; create table userScores_mv ( - `userid` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', + `userid` varchar(32) NOT NULL DEFAULT '', `score` int unsigned, `rankingScore` int unsigned, `reviewCount` int unsigned, @@ -864,7 +864,7 @@ unlock tables; drop table if exists gameRatingsSandbox0_mv; create table gameRatingsSandbox0_mv ( - `gameid` varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', + `gameid` varchar(32) NOT NULL DEFAULT '', `rated1` int unsigned, `rated2` int unsigned, `rated3` int unsigned, @@ -895,7 +895,7 @@ DROP PROCEDURE IF EXISTS refresh_gameRatingsSandbox0_mv; DELIMITER $$ CREATE PROCEDURE refresh_gameRatingsSandbox0_mv ( - IN new_gameid varchar(32) COLLATE latin1_german2_ci + IN new_gameid varchar(32) ) BEGIN select * @@ -961,3 +961,97 @@ call refresh_gameRatingsSandbox0_mv(NEW.gameid); CREATE TRIGGER reviews_delete AFTER DELETE ON reviews FOR EACH ROW call refresh_gameRatingsSandbox0_mv(OLD.gameid); + +-- The roundMedianTime function takes the exact median time in minutes +-- and rounds it. If the time is over an hour, round to the nearest 5 minutes. +-- Otherwise, round to the nearest minute. + +DELIMITER $$ + +CREATE FUNCTION roundMedianTime( + exact_median_in_minutes DECIMAL(5) +) +RETURNS INT(5) +DETERMINISTIC +BEGIN + DECLARE rounded_median_in_minutes INT(5); + IF exact_median_in_minutes > 60 THEN + SET rounded_median_in_minutes = (round(exact_median_in_minutes/5))*5; + ELSE + SET rounded_median_in_minutes = round(exact_median_in_minutes); + END IF; + RETURN (rounded_median_in_minutes); +END $$ + +DELIMITER ; + + +-- View to calculate the estimated play time (the rounded median time) of each game +CREATE VIEW `gametimes` AS + SELECT + DISTINCT gameid, + roundMedianTime( median(time_in_minutes) OVER (PARTITION BY gameid) ) as `rounded_median_time_in_minutes` + FROM playertimes; + + +-- Create a materialized view to store the data from the gametimes view +CREATE TABLE gametimes_mv ( + gameid VARCHAR(32) NOT NULL, + rounded_median_time_in_minutes INT(5) unsigned not null, + PRIMARY KEY (gameid), + KEY (rounded_median_time_in_minutes) +); + + + +-- Populate the gametimes_mv materialized view from the gametimes view +lock tables gametimes_mv write, gametimes read; +truncate table gametimes_mv; +insert into gametimes_mv select * from gametimes; +unlock tables; + + +-- Procedure to update one row of the gametimes_mv materialized view +DROP PROCEDURE IF EXISTS refresh_gametimes_mv; +DELIMITER $$ + +CREATE PROCEDURE refresh_gametimes_mv ( + IN new_gameid varchar(32) +) +BEGIN +select * +from gametimes +where gameid = new_gameid +into @gameid, + @rounded_median_time_in_minutes; +if @gameid is null then + delete from gametimes_mv where gameid = new_gameid; +else +insert into gametimes_mv +values ( + @gameid, + @rounded_median_time_in_minutes + ) on duplicate key +update gameid = @gameid, + rounded_median_time_in_minutes = @rounded_median_time_in_minutes; +END IF; +END; +$$ + +DELIMITER ; + + +-- Create triggers so that when an individual player time in the playertimes table is +-- updated, the rounded median time for that game (in the gametimes_mv materialized view) +-- will also be updated. +CREATE TRIGGER playertime_insert +AFTER INSERT ON playertimes FOR EACH ROW +call refresh_gametimes_mv(NEW.gameid); + +CREATE TRIGGER playertime_update +AFTER UPDATE ON playertimes FOR EACH ROW +call refresh_gametimes_mv(NEW.gameid); + +CREATE TRIGGER playertime_delete +AFTER DELETE ON playertimes FOR EACH ROW +call refresh_gametimes_mv(OLD.gameid);