From: Ant Zucaro Date: Mon, 29 Oct 2012 15:53:47 +0000 (-0400) Subject: Add indexes to the game and weapon stats tables. Store captimes. X-Git-Url: https://git.rm.cloudns.org/?a=commitdiff_plain;h=d4712af5c92fbff9ab6e9a4a9ef20d54097a998e;p=xonotic%2Fxonstatdb.git Add indexes to the game and weapon stats tables. Store captimes. --- diff --git a/tables/player_game_stats.tab b/tables/player_game_stats.tab index ac29f90..219e84a 100644 --- a/tables/player_game_stats.tab +++ b/tables/player_game_stats.tab @@ -24,6 +24,9 @@ CREATE TABLE xonstat.player_game_stats pushes integer, pushed integer, carrier_frags integer, + elo_delta numeric, + fastest_cap interval, + avg_latency numeric, create_dt timestamp without time zone NOT NULL DEFAULT (current_timestamp at time zone 'UTC'), CONSTRAINT player_game_stats_pk PRIMARY KEY (player_game_stat_id), CONSTRAINT player_game_stats_fk001 FOREIGN KEY (player_id) @@ -38,14 +41,15 @@ WITH ( ); CREATE INDEX player_game_stats_ix01 on player_game_stats(create_dt); +CREATE INDEX player_game_stats_ix02 on player_game_stats(game_id); ALTER TABLE xonstat.player_game_stats OWNER TO xonstat; - CREATE TABLE xonstat.player_game_stats_2011Q2 ( CHECK ( create_dt >= DATE '2011-04-01' AND create_dt < DATE '2011-07-01' ) ) INHERITS (player_game_stats); CREATE INDEX player_game_stats_2011Q2_ix01 on player_game_stats_2011Q2(create_dt); +CREATE INDEX player_game_stats_2011Q2_ix02 on player_game_stats_2011Q2(game_id); ALTER TABLE xonstat.player_game_stats_2011Q2 OWNER TO xonstat; @@ -54,6 +58,7 @@ CREATE TABLE xonstat.player_game_stats_2011Q3 ( ) INHERITS (player_game_stats); CREATE INDEX player_game_stats_2011Q3_ix01 on player_game_stats_2011Q3(create_dt); +CREATE INDEX player_game_stats_2011Q3_ix02 on player_game_stats_2011Q3(game_id); ALTER TABLE xonstat.player_game_stats_2011Q3 OWNER TO xonstat; @@ -62,6 +67,7 @@ CREATE TABLE xonstat.player_game_stats_2011Q4 ( ) INHERITS (player_game_stats); CREATE INDEX player_game_stats_2011Q4_ix01 on player_game_stats_2011Q4(create_dt); +CREATE INDEX player_game_stats_2011Q4_ix02 on player_game_stats_2011Q4(game_id); ALTER TABLE xonstat.player_game_stats_2011Q4 OWNER TO xonstat; @@ -70,6 +76,7 @@ CREATE TABLE xonstat.player_game_stats_2012Q1 ( ) INHERITS (player_game_stats); CREATE INDEX player_game_stats_2012Q1_ix01 on player_game_stats_2012Q1(create_dt); +CREATE INDEX player_game_stats_2012Q1_ix02 on player_game_stats_2012Q1(game_id); ALTER TABLE xonstat.player_game_stats_2012Q1 OWNER TO xonstat; @@ -78,6 +85,7 @@ CREATE TABLE xonstat.player_game_stats_2012Q2 ( ) INHERITS (player_game_stats); CREATE INDEX player_game_stats_2012Q2_ix01 on player_game_stats_2012Q2(create_dt); +CREATE INDEX player_game_stats_2012Q2_ix02 on player_game_stats_2012Q2(game_id); ALTER TABLE xonstat.player_game_stats_2012Q2 OWNER TO xonstat; @@ -86,6 +94,7 @@ CREATE TABLE xonstat.player_game_stats_2012Q3 ( ) INHERITS (player_game_stats); CREATE INDEX player_game_stats_2012Q3_ix01 on player_game_stats_2012Q3(create_dt); +CREATE INDEX player_game_stats_2012Q3_ix02 on player_game_stats_2012Q3(game_id); ALTER TABLE xonstat.player_game_stats_2012Q3 OWNER TO xonstat; @@ -94,6 +103,7 @@ CREATE TABLE xonstat.player_game_stats_2012Q4 ( ) INHERITS (player_game_stats); CREATE INDEX player_game_stats_2012Q4_ix01 on player_game_stats_2012Q4(create_dt); +CREATE INDEX player_game_stats_2012Q4_ix02 on player_game_stats_2012Q4(game_id); ALTER TABLE xonstat.player_game_stats_2012Q4 OWNER TO xonstat; @@ -102,6 +112,7 @@ CREATE TABLE xonstat.player_game_stats_2013Q1 ( ) INHERITS (player_game_stats); CREATE INDEX player_game_stats_2013Q1_ix01 on player_game_stats_2013Q1(create_dt); +CREATE INDEX player_game_stats_2013Q1_ix02 on player_game_stats_2013Q1(game_id); ALTER TABLE xonstat.player_game_stats_2013Q1 OWNER TO xonstat; @@ -110,5 +121,6 @@ CREATE TABLE xonstat.player_game_stats_2013Q2 ( ) INHERITS (player_game_stats); CREATE INDEX player_game_stats_2013Q2_ix01 on player_game_stats_2013Q2(create_dt); +CREATE INDEX player_game_stats_2013Q2_ix02 on player_game_stats_2013Q2(game_id); ALTER TABLE xonstat.player_game_stats_2013Q2 OWNER TO xonstat; diff --git a/tables/player_map_captimes.tab b/tables/player_map_captimes.tab new file mode 100644 index 0000000..c9960a3 --- /dev/null +++ b/tables/player_map_captimes.tab @@ -0,0 +1,28 @@ +CREATE TABLE xonstat.player_map_captimes +( + player_map_captime_id serial NOT NULL, + player_id integer NOT NULL, + map_id integer NOT NULL, + game_id bigint NOT NULL, + fastest_cap interval NOT NULL, + create_dt timestamp without time zone NOT NULL DEFAULT (current_timestamp at time zone 'UTC'), + CONSTRAINT player_map_captimes_pk PRIMARY KEY (player_map_captime_id), + CONSTRAINT player_map_captimes_uk01 UNIQUE (player_id, map_id), + CONSTRAINT player_map_captimes_fk01 FOREIGN KEY (player_id) + REFERENCES xonstat.players (player_id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT player_map_captimes_fk02 FOREIGN KEY (map_id) + REFERENCES xonstat.maps (map_id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION +-- I have no idea why this causes an integrity constraint error, +-- but it does. Since it is not critical, I'll drop it off for now, +-- until I get a clue as to why the error happens. +-- , + -- CONSTRAINT player_map_captimes_fk03 FOREIGN KEY (game_id) + -- REFERENCES xonstat.games (game_id) MATCH SIMPLE + -- ON UPDATE NO ACTION ON DELETE NO ACTION +) +WITH ( + OIDS=FALSE +); +ALTER TABLE xonstat.player_map_captimes OWNER TO xonstat; diff --git a/tables/player_weapon_stats.tab b/tables/player_weapon_stats.tab index 60954bb..54e4234 100644 --- a/tables/player_weapon_stats.tab +++ b/tables/player_weapon_stats.tab @@ -28,59 +28,79 @@ CREATE TABLE xonstat.player_weapon_stats WITH ( OIDS=FALSE ); + CREATE INDEX player_weap_stats_ix01 on player_weapon_stats(create_dt); +CREATE INDEX player_weap_stats_ix02 on player_weapon_stats(game_id); ALTER TABLE xonstat.player_weapon_stats OWNER TO xonstat; CREATE TABLE xonstat.player_weapon_stats_2011Q2 ( CHECK ( create_dt >= DATE '2011-04-01' AND create_dt < DATE '2011-07-01' ) ) INHERITS (player_weapon_stats); + CREATE INDEX player_weap_stats_2011Q2_ix01 on player_weapon_stats_2011Q2(create_dt); +CREATE INDEX player_weap_stats_2011Q2_ix02 on player_weapon_stats_2011Q2(game_id); ALTER TABLE xonstat.player_weapon_stats_2011Q2 OWNER TO xonstat; CREATE TABLE xonstat.player_weapon_stats_2011Q3 ( CHECK ( create_dt >= DATE '2011-07-01' AND create_dt < DATE '2011-10-01' ) ) INHERITS (player_weapon_stats); + CREATE INDEX player_weap_stats_2011Q3_ix01 on player_weapon_stats_2011Q3(create_dt); +CREATE INDEX player_weap_stats_2011Q3_ix02 on player_weapon_stats_2011Q3(game_id); ALTER TABLE xonstat.player_weapon_stats_2011Q3 OWNER TO xonstat; CREATE TABLE xonstat.player_weapon_stats_2011Q4 ( CHECK ( create_dt >= DATE '2011-10-01' AND create_dt < DATE '2012-01-01' ) ) INHERITS (player_weapon_stats); + CREATE INDEX player_weap_stats_2011Q4_ix01 on player_weapon_stats_2011Q4(create_dt); +CREATE INDEX player_weap_stats_2011Q4_ix02 on player_weapon_stats_2011Q4(game_id); ALTER TABLE xonstat.player_weapon_stats_2011Q4 OWNER TO xonstat; CREATE TABLE xonstat.player_weapon_stats_2012Q1 ( CHECK ( create_dt >= DATE '2012-01-01' AND create_dt < DATE '2012-04-01' ) ) INHERITS (player_weapon_stats); + CREATE INDEX player_weap_stats_2012Q1_ix01 on player_weapon_stats_2012Q1(create_dt); +CREATE INDEX player_weap_stats_2012Q1_ix02 on player_weapon_stats_2012Q1(game_id); ALTER TABLE xonstat.player_weapon_stats_2012Q1 OWNER TO xonstat; CREATE TABLE xonstat.player_weapon_stats_2012Q2 ( CHECK ( create_dt >= DATE '2012-04-01' AND create_dt < DATE '2012-07-01' ) ) INHERITS (player_weapon_stats); + CREATE INDEX player_weap_stats_2012Q2_ix01 on player_weapon_stats_2012Q2(create_dt); +CREATE INDEX player_weap_stats_2012Q2_ix02 on player_weapon_stats_2012Q2(game_id); ALTER TABLE xonstat.player_weapon_stats_2012Q2 OWNER TO xonstat; CREATE TABLE xonstat.player_weapon_stats_2012Q3 ( CHECK ( create_dt >= DATE '2012-07-01' AND create_dt < DATE '2012-10-01' ) ) INHERITS (player_weapon_stats); + CREATE INDEX player_weap_stats_2012Q3_ix01 on player_weapon_stats_2012Q3(create_dt); +CREATE INDEX player_weap_stats_2012Q3_ix02 on player_weapon_stats_2012Q3(game_id); ALTER TABLE xonstat.player_weapon_stats_2012Q3 OWNER TO xonstat; CREATE TABLE xonstat.player_weapon_stats_2012Q4 ( CHECK ( create_dt >= DATE '2012-10-01' AND create_dt < DATE '2013-01-01' ) ) INHERITS (player_weapon_stats); + CREATE INDEX player_weap_stats_2012Q4_ix01 on player_weapon_stats_2012Q4(create_dt); +CREATE INDEX player_weap_stats_2012Q4_ix02 on player_weapon_stats_2012Q4(game_id); ALTER TABLE xonstat.player_weapon_stats_2012Q4 OWNER TO xonstat; CREATE TABLE xonstat.player_weapon_stats_2013Q1 ( CHECK ( create_dt >= DATE '2013-01-01' AND create_dt < DATE '2013-04-01' ) ) INHERITS (player_weapon_stats); + CREATE INDEX player_weap_stats_2013Q1_ix01 on player_weapon_stats_2013Q1(create_dt); +CREATE INDEX player_weap_stats_2013Q1_ix02 on player_weapon_stats_2013Q1(game_id); ALTER TABLE xonstat.player_weapon_stats_2013Q1 OWNER TO xonstat; CREATE TABLE xonstat.player_weapon_stats_2013Q2 ( CHECK ( create_dt >= DATE '2013-04-01' AND create_dt < DATE '2013-07-01' ) ) INHERITS (player_weapon_stats); + CREATE INDEX player_weap_stats_2013Q2_ix01 on player_weapon_stats_2013Q2(create_dt); +CREATE INDEX player_weap_stats_2013Q2_ix02 on player_weapon_stats_2013Q2(game_id); ALTER TABLE xonstat.player_weapon_stats_2013Q2 OWNER TO xonstat;