diff --git a/Makefile b/Makefile index f4b3f9a..699fd21 100644 --- a/Makefile +++ b/Makefile @@ -9,7 +9,7 @@ baseball.db: baseball-transformed.db sql/load.sql cat sql/load.sql | sqlite3 baseball.db sqlite3 baseball.db "VACUUM" -baseball-transformed.db: baseball-raw.db sql/awards.sql sql/franchises.sql sql/teamseasons.sql sql/seasons.sql sql/parks.sql sql/collegeplaying.sql sql/schools.sql sql/people.sql sql/salaries.sql sql/batting.sql sql/pitching.sql sql/fielding.sql sql/appearances.sql sql/homegames.sql sql/seriespost.sql sql/fieldingofsplit.sql sql/teams.sql sql/leagues.sql sql/managers.sql sql/awardsmanagers.sql sql/battingpost.sql sql/fieldingpost.sql sql/pitchingpost.sql sql/appearancespost.sql sql/awardsshareplayers.sql sql/yearlyawards.sql sql/halloffame.sql sql/halloffamereqs.sql sql/awardsplayers.sql sql/parkaliases.sql sql/teamseasonshalf.sql sql/managershalf.sql +baseball-transformed.db: baseball-raw.db sql/awards.sql sql/franchises.sql sql/teamseasons.sql sql/seasons.sql sql/parks.sql sql/collegeplaying.sql sql/schools.sql sql/people.sql sql/salaries.sql sql/batting.sql sql/pitching.sql sql/fielding.sql sql/appearances.sql sql/homegames.sql sql/seriespost.sql sql/fieldingofsplit.sql sql/teams.sql sql/leagues.sql sql/managers.sql sql/awardsmanagers.sql sql/battingpost.sql sql/fieldingpost.sql sql/pitchingpost.sql sql/appearancespost.sql sql/awardsshareplayers.sql sql/yearlyawards.sql sql/halloffame.sql sql/halloffamereqs.sql sql/awardsplayers.sql sql/parkaliases.sql sql/teamseasonshalf.sql sql/managershalf.sql sql/allstarstartingpos.sql sql/allstars.sql sql/allstargames.sql rm -f baseball-transformed.db cp baseball-raw.db baseball-transformed.db cat sql/franchises.sql | sqlite3 baseball-transformed.db @@ -44,6 +44,9 @@ baseball-transformed.db: baseball-raw.db sql/awards.sql sql/franchises.sql sql/t cat sql/parkaliases.sql | sqlite3 baseball-transformed.db cat sql/teamseasonshalf.sql | sqlite3 baseball-transformed.db cat sql/managershalf.sql | sqlite3 baseball-transformed.db + cat sql/allstarstartingpos.sql | sqlite3 baseball-transformed.db + cat sql/allstars.sql | sqlite3 baseball-transformed.db + cat sql/allstargames.sql | sqlite3 baseball-transformed.db baseball-raw.db: rm -f baseball-raw.db diff --git a/sql/2nf/allstarfull.sql b/sql/2nf/allstarfull.sql deleted file mode 100644 index 9c4fb87..0000000 --- a/sql/2nf/allstarfull.sql +++ /dev/null @@ -1,37 +0,0 @@ -begin; -create table if not exists allstargames ( - "yearID" numeric, - "gameNum" numeric, - "gameID" text, - primary key("yearID","gameNum") -); - -insert into allstargames -select distinct yearid, gamenum, gameid -from allstarfull; - -alter table allstarfull drop column "gameID"; - -alter table allstarfull rename to "allstarstartingpos"; - -create table if not exists "allstars" ( - "playerID" text, - "yearID" text, - "gameNum" text, - "teamID" text, - "GP" numeric, - primary key("playerID","yearID","gameNum"), - foreign key("playerID") references "people"("playerID") -); - -insert into allstars -select distinct playerid, yearid, gamenum, teamid, gp -from allstarstartingpos; - -alter table allstarstartingpos drop column "teamid"; -alter table allstarstartingpos drop column "lgID"; -alter table allstarstartingpos drop column "gp"; - -delete from allstarstartingpos -where startingpos is null; -commit; diff --git a/sql/allstargames.sql b/sql/allstargames.sql new file mode 100644 index 0000000..f8b1b8e --- /dev/null +++ b/sql/allstargames.sql @@ -0,0 +1,26 @@ +begin; +attach database 'baseball-raw.db' as 'raw'; +create table if not exists allstargames ( + "year" numeric, + "gameNum" numeric, + "game" text +); + +insert into allstargames +select distinct yearid, gamenum, gameid +from "raw".allstarfull; + +-- fix game numbers for 1962 all-star games +update allstargames +set gamenum = 1 +where game = 'ALS196207100'; + +update allstargames +set gamenum = 2 +where game = 'NLS196207300'; + +-- 1945 all-star game wasn't played so some rows have no game id +update allstargames +set game = null +where game = ''; +commit; diff --git a/sql/allstars.sql b/sql/allstars.sql new file mode 100644 index 0000000..166a7f9 --- /dev/null +++ b/sql/allstars.sql @@ -0,0 +1,26 @@ +begin; +attach database 'baseball-raw.db' as 'raw'; +create table if not exists "allstars" ( + "player" text, + "year" text, + "gameNum" text, + "team" text, + "GP" numeric, + "gameID" text +); + +insert into allstars +select distinct playerid, yearid, gamenum, teamid, gp, gameid +from "raw".allstarfull; + +-- fix game numbers for 1962 all-star games +update allstars +set gamenum = 1 +where gameid = 'ALS196207100'; + +update allstars +set gamenum = 2 +where gameid = 'NLS196207300'; + +alter table allstars drop column "gameid"; +end; diff --git a/sql/allstarstartingpos.sql b/sql/allstarstartingpos.sql new file mode 100644 index 0000000..d4cb097 --- /dev/null +++ b/sql/allstarstartingpos.sql @@ -0,0 +1,24 @@ +begin; +alter table allstarfull rename to "allstarstartingpos"; + +-- fix game numbers for 1962 all-star games +update allstarstartingpos +set gamenum = 1 +where gameid = 'ALS196207100'; + +update allstarstartingpos +set gamenum = 2 +where gameid = 'NLS196207300'; + +alter table allstarstartingpos drop column "gameID"; +alter table allstarstartingpos drop column "teamid"; +alter table allstarstartingpos drop column "lgID"; +alter table allstarstartingpos drop column "gp"; + +update allstarstartingpos +set startingpos = null +where startingpos = ''; + +delete from allstarstartingpos +where startingpos is null; +commit; diff --git a/sql/corrections/allstarfull.sql b/sql/corrections/allstarfull.sql deleted file mode 100644 index ee3d552..0000000 --- a/sql/corrections/allstarfull.sql +++ /dev/null @@ -1,23 +0,0 @@ -begin; --- fix game numbers for 1962 all-star games -update allstarfull -set gamenum = 1 -where gameid = 'ALS196207100'; - -update allstarfull -set gamenum = 2 -where gameid = 'NLS196207300'; - --- david freese has two all-star entries for 2012, one in AL -delete from allstarfull -where playerid = 'freesda01' and yearid = 2012 and lgid = 'AL'; - --- 1945 all-star game wasn't played so some rows have no game id -update allstarfull -set gameid = null -where gameid = ''; - -update allstarfull -set startingpos = null -where startingpos = ''; -commit; diff --git a/sql/keys/allstarfull.sql b/sql/keys/allstarfull.sql deleted file mode 100644 index 2fde35a..0000000 --- a/sql/keys/allstarfull.sql +++ /dev/null @@ -1,18 +0,0 @@ -BEGIN; -CREATE TABLE "pk_allstarfull" ( - "playerID" NUMERIC, - "yearID" NUMERIC, - "gameNum" NUMERIC, - "gameID" NUMERIC, - "teamID" NUMERIC, - "lgID" NUMERIC, - "GP" NUMERIC, - "startingPos" NUMERIC, - primary key("playerID","yearID","gameNum","startingPos"), - foreign key("playerID") references "people"("playerID") -); - -INSERT INTO "pk_allstarfull" SELECT DISTINCT * FROM "allstarfull"; -DROP TABLE "allstarfull"; -ALTER TABLE "pk_allstarfull" RENAME TO "allstarfull"; -COMMIT; diff --git a/sql/load.sql b/sql/load.sql index dfd949a..065abd1 100644 --- a/sql/load.sql +++ b/sql/load.sql @@ -609,4 +609,38 @@ CREATE TABLE IF NOT EXISTS "managershalf" ( ); insert into managershalf select distinct * from "transformed".managershalf; + +CREATE TABLE "allstarstartingpos" ( + "player" NUMERIC, + "year" NUMERIC, + "gameNum" NUMERIC, + "startingPos" NUMERIC, + primary key("player","year","gameNum","startingPos"), + foreign key("player","year","gameNum") references "allstars"("player","year","gameNum") +); + +insert into allstarstartingpos select distinct * from "transformed".allstarstartingpos; + +create table if not exists allstargames ( + "year" numeric, + "gameNum" numeric, + "game" text, + primary key("year","gameNum"), + foreign key("year") references "seasons"("year") +); + +insert into allstargames select distinct * from "transformed".allstargames; + +create table if not exists "allstars" ( + "player" text, + "year" text, + "gameNum" text, + "team" text, + "GP" numeric, + primary key("player","year","gameNum"), + foreign key("year","gameNum") references "allstargames"("year","gameNum"), + foreign key("player","year","team") references "appearances"("player","year","team") +); + +insert into allstars select distinct * from "transformed".allstars; COMMIT;