From d8c91e390918ea6b16404cfe0ca36ca1d7753b49 Mon Sep 17 00:00:00 2001 From: Nick Griffey Date: Sun, 28 Jan 2024 00:09:06 -0600 Subject: [PATCH] move postseasons tables --- Makefile | 6 ++- sql/appearancespost.sql | 19 ++++++++ sql/battingpost.sql | 4 ++ sql/fieldingpost.sql | 4 ++ sql/keys/battingpost.sql | 32 ------------- sql/keys/fieldingpost.sql | 27 ----------- sql/keys/pitchingpost.sql | 40 ---------------- sql/load.sql | 98 +++++++++++++++++++++++++++++++++++++++ sql/pitchingpost.sql | 4 ++ 9 files changed, 134 insertions(+), 100 deletions(-) create mode 100644 sql/appearancespost.sql create mode 100644 sql/battingpost.sql create mode 100644 sql/fieldingpost.sql delete mode 100644 sql/keys/battingpost.sql delete mode 100644 sql/keys/fieldingpost.sql delete mode 100644 sql/keys/pitchingpost.sql create mode 100644 sql/pitchingpost.sql diff --git a/Makefile b/Makefile index 334ccf2..fca7f62 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 +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 rm -f baseball-transformed.db cp baseball-raw.db baseball-transformed.db cat sql/franchises.sql | sqlite3 baseball-transformed.db @@ -32,6 +32,10 @@ baseball-transformed.db: baseball-raw.db sql/awards.sql sql/franchises.sql sql/t cat sql/leagues.sql | sqlite3 baseball-transformed.db cat sql/managers.sql | sqlite3 baseball-transformed.db cat sql/awardsmanagers.sql | sqlite3 baseball-transformed.db + cat sql/fieldingpost.sql | sqlite3 baseball-transformed.db + cat sql/battingpost.sql | sqlite3 baseball-transformed.db + cat sql/pitchingpost.sql | sqlite3 baseball-transformed.db + cat sql/appearancespost.sql | sqlite3 baseball-transformed.db baseball-raw.db: rm -f baseball-raw.db diff --git a/sql/appearancespost.sql b/sql/appearancespost.sql new file mode 100644 index 0000000..c33b65e --- /dev/null +++ b/sql/appearancespost.sql @@ -0,0 +1,19 @@ +begin; +attach database 'baseball-raw.db' as 'raw'; + +create table if not exists appearancespost ( + "year" numeric, + "player" text, + "team" text +); + +insert into appearancespost +select distinct yearID, playerID, teamID +from 'raw'.battingpost +union +select distinct yearID, playerID, teamID +from 'raw'.pitchingpost +union +select distinct yearID, playerID, teamID +from 'raw'.fieldingpost; +commit; diff --git a/sql/battingpost.sql b/sql/battingpost.sql new file mode 100644 index 0000000..1f82b17 --- /dev/null +++ b/sql/battingpost.sql @@ -0,0 +1,4 @@ +begin; +alter table battingpost drop column "lgID"; +alter table battingpost drop column "teamID"; +commit; diff --git a/sql/fieldingpost.sql b/sql/fieldingpost.sql new file mode 100644 index 0000000..736791f --- /dev/null +++ b/sql/fieldingpost.sql @@ -0,0 +1,4 @@ +begin; +alter table fieldingpost drop column "lgID"; +alter table fieldingpost drop column "teamID"; +commit; diff --git a/sql/keys/battingpost.sql b/sql/keys/battingpost.sql deleted file mode 100644 index bd2e864..0000000 --- a/sql/keys/battingpost.sql +++ /dev/null @@ -1,32 +0,0 @@ -begin; -CREATE TABLE IF NOT EXISTS "pk_battingpost" ( - "yearID" NUMERIC, - "round" NUMERIC, - "playerID" TEXT, - "teamID" TEXT, - "lgID" TEXT, - "G" NUMERIC, - "AB" NUMERIC, - "R" NUMERIC, - "H" NUMERIC, - "2B" NUMERIC, - "3B" NUMERIC, - "HR" NUMERIC, - "RBI" NUMERIC, - "SB" NUMERIC, - "CS" NUMERIC, - "BB" NUMERIC, - "SO" NUMERIC, - "IBB" NUMERIC, - "HBP" NUMERIC, - "SH" NUMERIC, - "SF" NUMERIC, - "GIDP" NUMERIC, - PRIMARY KEY("yearID","playerID","round"), - foreign key("playerID") references "people"("playerID") -); - -INSERT INTO "pk_battingpost" SELECT DISTINCT * FROM "battingpost"; -DROP TABLE "battingpost"; -ALTER TABLE "pk_battingpost" RENAME TO "battingpost"; -commit; diff --git a/sql/keys/fieldingpost.sql b/sql/keys/fieldingpost.sql deleted file mode 100644 index 3696d22..0000000 --- a/sql/keys/fieldingpost.sql +++ /dev/null @@ -1,27 +0,0 @@ -BEGIN; -CREATE TABLE IF NOT EXISTS "pk_fieldingpost" ( - "playerID" TEXT, - "yearID" NUMERIC, - "teamID" TEXT, - "lgID" TEXT, - "round" NUMERIC, - "POS" TEXT, - "G" NUMERIC, - "GS" NUMERIC, - "InnOuts" NUMERIC, - "PO" NUMERIC, - "A" NUMERIC, - "E" NUMERIC, - "DP" NUMERIC, - "TP" NUMERIC, - "PB" NUMERIC, - "SB" NUMERIC, - "CS" NUMERIC, - PRIMARY KEY("playerID","yearID","round","POS"), - foreign key("playerID") references "people"("playerID") -); - -INSERT INTO "pk_fieldingpost" SELECT DISTINCT * FROM "fieldingpost"; -DROP TABLE "fieldingpost"; -ALTER TABLE "pk_fieldingpost" RENAME TO "fieldingpost"; -COMMIT; diff --git a/sql/keys/pitchingpost.sql b/sql/keys/pitchingpost.sql deleted file mode 100644 index daecda2..0000000 --- a/sql/keys/pitchingpost.sql +++ /dev/null @@ -1,40 +0,0 @@ -BEGIN; -CREATE TABLE IF NOT EXISTS "pk_pitchingpost" ( - "playerID" TEXT, - "yearID" NUMERIC, - "round" NUMERIC, - "teamID" TEXT, - "lgID" TEXT, - "W" NUMERIC, - "L" NUMERIC, - "G" NUMERIC, - "GS" NUMERIC, - "CG" NUMERIC, - "SHO" NUMERIC, - "SV" NUMERIC, - "IPouts" NUMERIC, - "H" NUMERIC, - "ER" NUMERIC, - "HR" NUMERIC, - "BB" NUMERIC, - "SO" NUMERIC, - "BAOpp" NUMERIC, - "ERA" NUMERIC, - "IBB" NUMERIC, - "WP" NUMERIC, - "HBP" NUMERIC, - "BK" NUMERIC, - "BFP" NUMERIC, - "GF" NUMERIC, - "R" NUMERIC, - "SH" NUMERIC, - "SF" NUMERIC, - "GIDP" NUMERIC, - PRIMARY KEY("playerID","yearID","round"), - foreign key("playerID") references "people"("playerID") -); - -INSERT INTO "pk_pitchingpost" SELECT DISTINCT * FROM "pitchingpost"; -DROP TABLE "pitchingpost"; -ALTER TABLE "pk_pitchingpost" RENAME TO "pitchingpost"; -COMMIT; diff --git a/sql/load.sql b/sql/load.sql index 54d761f..9d38fd9 100644 --- a/sql/load.sql +++ b/sql/load.sql @@ -388,4 +388,102 @@ CREATE TABLE IF NOT EXISTS "awardsmanagers" ( ); insert into awardsmanagers select distinct * from "transformed"."awardsmanagers"; + +CREATE TABLE IF NOT EXISTS "battingpost" ( + "year" NUMERIC, + "round" NUMERIC, + "player" TEXT, + "G" NUMERIC, + "AB" NUMERIC, + "R" NUMERIC, + "H" NUMERIC, + "2B" NUMERIC, + "3B" NUMERIC, + "HR" NUMERIC, + "RBI" NUMERIC, + "SB" NUMERIC, + "CS" NUMERIC, + "BB" NUMERIC, + "SO" NUMERIC, + "IBB" NUMERIC, + "HBP" NUMERIC, + "SH" NUMERIC, + "SF" NUMERIC, + "GIDP" NUMERIC, + PRIMARY KEY("year","player","round"), + foreign key("player") references "people"("ID"), + foreign key("year") references "seasons"("year") +); + +insert into battingpost select distinct * from "transformed"."battingpost"; + +CREATE TABLE IF NOT EXISTS "fieldingpost" ( + "player" TEXT, + "year" NUMERIC, + "round" NUMERIC, + "POS" TEXT, + "G" NUMERIC, + "GS" NUMERIC, + "InnOuts" NUMERIC, + "PO" NUMERIC, + "A" NUMERIC, + "E" NUMERIC, + "DP" NUMERIC, + "TP" NUMERIC, + "PB" NUMERIC, + "SB" NUMERIC, + "CS" NUMERIC, + PRIMARY KEY("player","year","round","POS"), + foreign key("player") references "people"("ID"), + foreign key("year") references "seasons"("year") +); + +insert into fieldingpost select distinct * from "transformed"."fieldingpost"; + +CREATE TABLE IF NOT EXISTS "pitchingpost" ( + "player" TEXT, + "year" NUMERIC, + "round" NUMERIC, + "W" NUMERIC, + "L" NUMERIC, + "G" NUMERIC, + "GS" NUMERIC, + "CG" NUMERIC, + "SHO" NUMERIC, + "SV" NUMERIC, + "IPouts" NUMERIC, + "H" NUMERIC, + "ER" NUMERIC, + "HR" NUMERIC, + "BB" NUMERIC, + "SO" NUMERIC, + "BAOpp" NUMERIC, + "ERA" NUMERIC, + "IBB" NUMERIC, + "WP" NUMERIC, + "HBP" NUMERIC, + "BK" NUMERIC, + "BFP" NUMERIC, + "GF" NUMERIC, + "R" NUMERIC, + "SH" NUMERIC, + "SF" NUMERIC, + "GIDP" NUMERIC, + PRIMARY KEY("player","year","round"), + foreign key("player") references "people"("ID"), + foreign key("year") references "seasons"("year") +); + +insert into pitchingpost select distinct * from "transformed"."pitchingpost"; + +create table if not exists appearancespost ( + "year" numeric, + "player" text, + "team" text, + primary key("year","player"), + foreign key("player") references "people"("ID"), + foreign key("year","team") references "teamseasons"("year","team") +); + +insert into appearancespost select distinct * from "transformed"."appearancespost"; COMMIT; diff --git a/sql/pitchingpost.sql b/sql/pitchingpost.sql new file mode 100644 index 0000000..fb1f7f8 --- /dev/null +++ b/sql/pitchingpost.sql @@ -0,0 +1,4 @@ +begin; +alter table pitchingpost drop column "lgID"; +alter table pitchingpost drop column "teamID"; +commit;