Get rid of load.sql

This commit is contained in:
Nick Griffey 2024-01-31 00:09:39 -06:00
parent ac9a713457
commit 321fea8d5d
40 changed files with 842 additions and 720 deletions

View File

@ -4,52 +4,48 @@ bbdb = baseballdatabank-2023.1
db: baseball.db
baseball.db: baseball-transformed.db sql/load.sql
baseball.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 sql/playerstints.sql
rm -f baseball.db
cat sql/load.sql | sqlite3 baseball.db
cat sql/allstargames.sql | sqlite3 baseball.db
cat sql/allstars.sql | sqlite3 baseball.db
cat sql/allstarstartingpos.sql | sqlite3 baseball.db
cat sql/appearancespost.sql | sqlite3 baseball.db
cat sql/appearances.sql | sqlite3 baseball.db
cat sql/awardsmanagers.sql | sqlite3 baseball.db
cat sql/awardsplayers.sql | sqlite3 baseball.db
cat sql/awardssharemanagers.sql | sqlite3 baseball.db
cat sql/awardsshareplayers.sql | sqlite3 baseball.db
cat sql/awards.sql | sqlite3 baseball.db
cat sql/battingpost.sql | sqlite3 baseball.db
cat sql/batting.sql | sqlite3 baseball.db
cat sql/collegeplaying.sql | sqlite3 baseball.db
cat sql/fieldingofsplit.sql | sqlite3 baseball.db
cat sql/fieldingof.sql | sqlite3 baseball.db
cat sql/fieldingpost.sql | sqlite3 baseball.db
cat sql/fielding.sql | sqlite3 baseball.db
cat sql/franchises.sql | sqlite3 baseball.db
cat sql/halloffamereqs.sql | sqlite3 baseball.db
cat sql/halloffame.sql | sqlite3 baseball.db
cat sql/homegames.sql | sqlite3 baseball.db
cat sql/leagues.sql | sqlite3 baseball.db
cat sql/managershalf.sql | sqlite3 baseball.db
cat sql/managers.sql | sqlite3 baseball.db
cat sql/parkaliases.sql | sqlite3 baseball.db
cat sql/parks.sql | sqlite3 baseball.db
cat sql/people.sql | sqlite3 baseball.db
cat sql/pitchingpost.sql | sqlite3 baseball.db
cat sql/pitching.sql | sqlite3 baseball.db
cat sql/playerstints.sql | sqlite3 baseball.db
cat sql/salaries.sql | sqlite3 baseball.db
cat sql/schools.sql | sqlite3 baseball.db
cat sql/seasons.sql | sqlite3 baseball.db
cat sql/seriespost.sql | sqlite3 baseball.db
cat sql/teamseasonshalf.sql | sqlite3 baseball.db
cat sql/teamseasons.sql | sqlite3 baseball.db
cat sql/teams.sql | sqlite3 baseball.db
cat sql/yearlyawards.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 sql/allstarstartingpos.sql sql/allstars.sql sql/allstargames.sql sql/playerstints.sql
rm -f baseball-transformed.db
cp baseball-raw.db baseball-transformed.db
cat sql/allstargames.sql | sqlite3 baseball-transformed.db
cat sql/allstars.sql | sqlite3 baseball-transformed.db
cat sql/allstarstartingpos.sql | sqlite3 baseball-transformed.db
cat sql/appearancespost.sql | sqlite3 baseball-transformed.db
cat sql/appearances.sql | sqlite3 baseball-transformed.db
cat sql/awardsmanagers.sql | sqlite3 baseball-transformed.db
cat sql/awardsplayers.sql | sqlite3 baseball-transformed.db
cat sql/awardsshareplayers.sql | sqlite3 baseball-transformed.db
cat sql/awards.sql | sqlite3 baseball-transformed.db
cat sql/battingpost.sql | sqlite3 baseball-transformed.db
cat sql/batting.sql | sqlite3 baseball-transformed.db
cat sql/collegeplaying.sql | sqlite3 baseball-transformed.db
cat sql/fieldingofsplit.sql | sqlite3 baseball-transformed.db
cat sql/fieldingpost.sql | sqlite3 baseball-transformed.db
cat sql/fielding.sql | sqlite3 baseball-transformed.db
cat sql/franchises.sql | sqlite3 baseball-transformed.db
cat sql/halloffamereqs.sql | sqlite3 baseball-transformed.db
cat sql/halloffame.sql | sqlite3 baseball-transformed.db
cat sql/homegames.sql | sqlite3 baseball-transformed.db
cat sql/leagues.sql | sqlite3 baseball-transformed.db
cat sql/managershalf.sql | sqlite3 baseball-transformed.db
cat sql/managers.sql | sqlite3 baseball-transformed.db
cat sql/parkaliases.sql | sqlite3 baseball-transformed.db
cat sql/parks.sql | sqlite3 baseball-transformed.db
cat sql/people.sql | sqlite3 baseball-transformed.db
cat sql/pitchingpost.sql | sqlite3 baseball-transformed.db
cat sql/pitching.sql | sqlite3 baseball-transformed.db
cat sql/playerstints.sql | sqlite3 baseball-transformed.db
cat sql/salaries.sql | sqlite3 baseball-transformed.db
cat sql/schools.sql | sqlite3 baseball-transformed.db
cat sql/seasons.sql | sqlite3 baseball-transformed.db
cat sql/seriespost.sql | sqlite3 baseball-transformed.db
cat sql/teamseasonshalf.sql | sqlite3 baseball-transformed.db
cat sql/teamseasons.sql | sqlite3 baseball-transformed.db
cat sql/teams.sql | sqlite3 baseball-transformed.db
cat sql/yearlyawards.sql | sqlite3 baseball-transformed.db
baseball-raw.db:
rm -f baseball-raw.db
sqlite3 baseball-raw.db ".import --csv $(bbdb)/core/AllstarFull.csv allstarfull"

View File

@ -1,6 +1,6 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create table if not exists allstargames (
create temp table if not exists "allstargames" (
"year" numeric,
"gameNum" numeric,
"game" text
@ -23,4 +23,14 @@ where game = 'NLS196207300';
update allstargames
set game = null
where game = '';
create table if not exists allstargames (
"year" numeric,
"gameNum" numeric,
"game" text,
primary key("year","gameNum"),
foreign key("year") references "seasons"("year")
);
insert into main.allstargames select distinct * from temp.allstargames;
commit;

View File

@ -1,6 +1,6 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create table if not exists "allstars" (
create temp table if not exists "allstars" (
"player" text,
"year" text,
"gameNum" text,
@ -45,4 +45,17 @@ where player = 'chapmbe01' and year = 1933;
update allstars
set team = 'ATL'
where player = 'contrwi02' and year = 2022;
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 main.allstars select distinct * from temp.allstars;
end;

View File

@ -1,5 +1,18 @@
begin;
alter table allstarfull rename to "allstarstartingpos";
attach database 'baseball-raw.db' as 'raw';
CREATE TEMP TABLE "allstarstartingpos" (
"player" NUMERIC,
"year" NUMERIC,
"gameNum" NUMERIC,
"league" NUMERIC,
"startingPos" NUMERIC,
"gameid" text
);
insert into "allstarstartingpos"
select distinct playerid, yearid, gamenum, lgid, startingpos, gameid
from "raw".allstarfull;
-- fix game numbers for 1962 all-star games
update allstarstartingpos
@ -12,11 +25,9 @@ where gameid = 'NLS196207300';
-- rocky colavito was a reserve, not starter
delete from allstarstartingpos
where gameid = 'ALS196207100' and playerid = 'colavro01';
where gameid = 'ALS196207100' and player = 'colavro01';
alter table allstarstartingpos drop column "gameID";
alter table allstarstartingpos drop column "teamid";
alter table allstarstartingpos drop column "gp";
alter table allstarstartingpos drop column "gameid";
update allstarstartingpos
set startingpos = null
@ -24,4 +35,17 @@ where startingpos = '';
delete from allstarstartingpos
where startingpos is null;
CREATE TABLE "allstarstartingpos" (
"player" NUMERIC,
"year" NUMERIC,
"gameNum" NUMERIC,
"league" NUMERIC,
"startingPos" NUMERIC,
primary key("year","gameNum","league","startingPos"),
foreign key("player","year","gameNum") references "allstars"("player","year","gameNum"),
foreign key("league") references "leagues"("ID")
);
insert into main.allstarstartingpos select distinct * from temp.allstarstartingpos;
commit;

View File

@ -1,5 +1,10 @@
begin;
alter table "appearances" drop column "lgID";
attach database 'baseball-raw.db' as 'raw';
create temp table appearances as
select * from "raw".appearances;
alter table appearances drop column "lgID";
update appearances
set teamid = 'WS9'
@ -8,4 +13,32 @@ where teamid = 'WAS' and yearid between 1891 and 1899;
update appearances
set teamid = 'PHP'
where teamid = 'PH4' and yearid between 1890 and 1891;
CREATE TABLE IF NOT EXISTS "appearances" (
"year" NUMERIC,
"team" TEXT,
"player" TEXT,
"G_all" NUMERIC,
"GS" NUMERIC,
"G_batting" NUMERIC,
"G_defense" NUMERIC,
"G_p" NUMERIC,
"G_c" NUMERIC,
"G_1b" NUMERIC,
"G_2b" NUMERIC,
"G_3b" NUMERIC,
"G_ss" NUMERIC,
"G_lf" NUMERIC,
"G_cf" NUMERIC,
"G_rf" NUMERIC,
"G_of" NUMERIC,
"G_dh" NUMERIC,
"G_ph" NUMERIC,
"G_pr" NUMERIC,
PRIMARY KEY("year","team","player"),
foreign key("player") references "people"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into main.appearances select distinct * from temp.appearances;
commit;

View File

@ -1,7 +1,7 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create table if not exists appearancespost (
create temp table if not exists appearancespost (
"year" numeric,
"player" text,
"team" text
@ -16,4 +16,15 @@ from 'raw'.pitchingpost
union
select distinct yearID, playerID, teamID
from 'raw'.fieldingpost;
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 main.appearancespost select distinct * from temp."appearancespost";
commit;

View File

@ -1,6 +1,6 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create table if not exists "awards" (
create temp table if not exists "awards" (
"ID" text
);
@ -10,4 +10,12 @@ from "raw".awardsmanagers
union
select distinct awardID
from "raw".awardsplayers;
create table if not exists "awards" (
"ID" text,
primary key("ID")
);
insert into main.awards
select distinct * from temp."awards";
commit;

View File

@ -1,3 +1,21 @@
begin;
alter table awardsmanagers drop column "tie";
attach database 'baseball-raw.db' as 'raw';
create temp table "awardsmanagers" as
select * from "raw".awardsmanagers;
alter table temp.awardsmanagers drop column "tie";
CREATE TABLE IF NOT EXISTS main."awardsmanagers" (
"manager" TEXT,
"award" TEXT,
"year" NUMERIC,
"league" TEXT,
"notes" TEXT,
PRIMARY KEY("manager","award","year","league"),
foreign key("manager") references "people"("ID"),
foreign key("award","year","league") references "yearlyawards"("award","year","league")
);
insert into main.awardsmanagers select distinct * from temp."awardsmanagers";
commit;

View File

@ -1,3 +1,20 @@
begin;
alter table awardsplayers drop column "tie";
attach database 'baseball-raw.db' as 'raw';
create temp table awardsplayers as
select * from "raw".awardsplayers;
alter table temp.awardsplayers drop column "tie";
CREATE TABLE IF NOT EXISTS main."awardsplayers" (
"player" TEXT,
"award" TEXT,
"year" NUMERIC,
"league" TEXT,
"notes" TEXT,
PRIMARY KEY("award","year","league","notes","player"),
foreign key("player") references "people"("ID"),
foreign key("award","year","league") references "yearlyawards"("award","year","league")
);
insert into main.awardsplayers select distinct * from temp.awardsplayers;
commit;

View File

@ -0,0 +1,18 @@
begin;
attach database 'baseball-raw.db' as 'raw';
CREATE TABLE IF NOT EXISTS "awardssharemanagers" (
"award" TEXT,
"year" NUMERIC,
"league" TEXT,
"manager" TEXT,
"pointsWon" NUMERIC,
"pointsMax" NUMERIC,
"votesFirst" NUMERIC,
PRIMARY KEY("manager","award","year","league"),
foreign key("manager") references "people"("ID"),
foreign key("award","year","league") references "yearlyawards"("award","year","league")
);
insert into awardssharemanagers select distinct * from "raw"."awardssharemanagers";
commit;

View File

@ -1,9 +1,29 @@
begin;
update awardsshareplayers
attach database 'baseball-raw.db' as 'raw';
create temp table awardsshareplayers as
select * from "raw".awardsshareplayers;
update temp.awardsshareplayers
set awardid = 'Cy Young Award'
where awardid = 'Cy Young';
update awardsshareplayers
update temp.awardsshareplayers
set awardid = 'Most Valuable Player'
where awardid = 'MVP';
CREATE TABLE IF NOT EXISTS main."awardsshareplayers" (
"award" TEXT,
"year" NUMERIC,
"league" TEXT,
"player" TEXT,
"pointsWon" NUMERIC,
"pointsMax" NUMERIC,
"votesFirst" NUMERIC,
PRIMARY KEY("award","year","player","league"),
foreign key("player") references "people"("ID"),
foreign key("award","year","league") references "yearlyawards"("award","year","league")
);
insert into main.awardsshareplayers select distinct * from temp."awardsshareplayers";
commit;

View File

@ -1,4 +1,36 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table batting as
select * from "raw".batting;
alter table batting drop column "lgID";
alter table batting drop column "teamID";
CREATE TABLE IF NOT EXISTS main."batting" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"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("player","year","stint"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into main.batting select distinct * from temp."batting";
commit;

View File

@ -1,4 +1,37 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table battingpost as
select * from "raw".battingpost;
alter table battingpost drop column "lgID";
alter table battingpost drop column "teamID";
CREATE TABLE IF NOT EXISTS main."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","year") references "appearancespost"("player","year"),
foreign key("year","round") references "seriespost"("year","round")
);
insert into main.battingpost select distinct * from temp."battingpost";
commit;

View File

@ -1,4 +1,9 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table collegeplaying as
select * from "raw".collegeplaying;
-- fix school id
update collegeplaying
set schoolID = 'cwpost'
@ -8,4 +13,15 @@ where schoolID = 'ctpostu';
-- another source that says otherwise
delete from collegeplaying
where playerid = 'woodsdi01';
CREATE TABLE IF NOT EXISTS main."collegeplaying" (
"player" TEXT,
"school" TEXT,
"year" NUMERIC,
PRIMARY KEY("player","year","school"),
foreign key("player") references "people"("ID"),
foreign key("school") references "schools"("ID")
);
insert into main.collegeplaying select distinct * from temp."collegeplaying";
commit;

View File

@ -1,4 +1,32 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table fielding as
select * from "raw".fielding;
alter table fielding drop column "lgID";
alter table fielding drop column "teamID";
CREATE TABLE IF NOT EXISTS main."fielding" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"POS" TEXT,
"G" NUMERIC,
"GS" NUMERIC,
"InnOuts" NUMERIC,
"PO" NUMERIC,
"A" NUMERIC,
"E" NUMERIC,
"DP" NUMERIC,
"PB" NUMERIC,
"WP" NUMERIC,
"SB" NUMERIC,
"CS" NUMERIC,
"ZR" NUMERIC,
PRIMARY KEY("player","year","stint","POS"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into main.fielding select distinct * from temp."fielding";
commit;

15
sql/fieldingof.sql Normal file
View File

@ -0,0 +1,15 @@
begin;
attach database 'baseball-raw.db' as 'raw';
CREATE TABLE IF NOT EXISTS "fieldingof" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"Glf" NUMERIC,
"Gcf" NUMERIC,
"Grf" NUMERIC,
PRIMARY KEY("player","year","stint"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into fieldingof select distinct * from "raw"."fieldingof";
commit;

View File

@ -1,4 +1,32 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table fieldingofsplit as
select * from fieldingofsplit;
alter table fieldingofsplit drop column "lgID";
alter table fieldingofsplit drop column "teamID";
CREATE TABLE IF NOT EXISTS main."fieldingofsplit" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"POS" TEXT,
"G" NUMERIC,
"GS" NUMERIC,
"InnOuts" NUMERIC,
"PO" NUMERIC,
"A" NUMERIC,
"E" NUMERIC,
"DP" NUMERIC,
"PB" NUMERIC,
"WP" NUMERIC,
"SB" NUMERIC,
"CS" NUMERIC,
"ZR" NUMERIC,
PRIMARY KEY("player","year","stint","POS"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into main.fieldingofsplit select distinct * from temp."fieldingofsplit";
commit;

View File

@ -1,4 +1,32 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table fieldingpost as
select * from "raw".fieldingpost;
alter table fieldingpost drop column "lgID";
alter table fieldingpost drop column "teamID";
CREATE TABLE IF NOT EXISTS main."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","year") references "appearancespost"("player","year"),
foreign key("year","round") references "seriespost"("year","round")
);
insert into main.fieldingpost select distinct * from temp."fieldingpost";
commit;

View File

@ -1,3 +1,17 @@
begin;
alter table "teamsfranchises" rename to "franchises";
attach database 'baseball-raw.db' as 'raw';
create temp table franchises as
select * from "raw".teamsfranchises;
CREATE TABLE IF NOT EXISTS main."franchises" (
"ID" TEXT,
"name" TEXT,
"active" TEXT,
"NAassoc" TEXT,
PRIMARY KEY("ID")
);
insert into main.franchises
select distinct * from temp."franchises";
commit;

View File

@ -1,4 +1,9 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table halloffame as
select * from "raw".halloffame;
update halloffame
set ballots = null
where ballots = '' or ballots = 'NA';
@ -10,4 +15,18 @@ where needed = '' or needed = 'NA';
alter table halloffame drop column "ballots";
alter table halloffame drop column "needed";
alter table halloffame drop column "needed_note";
CREATE TABLE IF NOT EXISTS main."halloffame" (
"player" TEXT,
"year" NUMERIC,
"votedBy" TEXT,
"votes" NUMERIC,
"inducted" TEXT,
"category" TEXT,
PRIMARY KEY("player","year","votedBy")
foreign key("player") references "people"("ID"),
foreign key("year","votedBy") references "halloffamereqs"("year","votedBy")
);
insert into main.halloffame select distinct * from temp.halloffame;
commit;

View File

@ -1,6 +1,6 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create table if not exists "halloffamereqs" (
create temp table if not exists "halloffamereqs" (
"yearID" numeric,
"votedBy" text,
"ballots" numeric,
@ -11,4 +11,16 @@ create table if not exists "halloffamereqs" (
insert into halloffamereqs
select distinct yearid, votedby, ballots, needed, "needed_note"
from "raw".halloffame;
create table if not exists main."halloffamereqs" (
"year" numeric,
"votedBy" text,
"ballots" numeric,
"needed" numeric,
"needed_note" text,
primary key("year","votedBy"),
foreign key("year") references "seasons"("year")
);
insert into main.halloffamereqs select distinct * from temp.halloffamereqs;
commit;

View File

@ -1,4 +1,9 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table homegames as
select * from "raw".homegames;
alter table "homegames" drop column "league.key";
update homegames
@ -8,4 +13,20 @@ where "team.key" = 'WAS' and "year.key" between 1891 and 1899;
update homegames
set "team.key" = 'PHP'
where "team.key" = 'PH4' and "year.key" between 1890 and 1891;
CREATE TABLE IF NOT EXISTS main."homegames" (
"year" NUMERIC,
"team" TEXT,
"park" TEXT,
"first" TEXT,
"last" TEXT,
"games" NUMERIC,
"openings" NUMERIC,
"attendance" NUMERIC,
PRIMARY KEY("year","team","park"),
foreign key("park") references "parks"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into main.homegames select distinct * from temp."homegames";
commit;

View File

@ -1,5 +1,7 @@
begin;
create table if not exists "leagues" (
attach database 'baseball-raw.db' as 'raw';
create temp table if not exists "leagues" (
"ID" text,
"name" text
);
@ -12,4 +14,12 @@ insert into leagues values
("PL","Player's League"),
("AL","American League"),
("FL","Federal League");
create table if not exists main."leagues" (
"ID" text,
"name" text,
primary key("ID")
);
insert into main.leagues select distinct * from temp."leagues";
commit;

View File

@ -1,652 +0,0 @@
BEGIN;
attach database 'baseball-transformed.db' as 'transformed';
create table if not exists "awards" (
"ID" text,
primary key("ID")
);
insert into awards
select distinct * from "transformed"."awards";
CREATE TABLE IF NOT EXISTS "franchises" (
"ID" TEXT,
"name" TEXT,
"active" TEXT,
"NAassoc" TEXT,
PRIMARY KEY("ID")
);
insert into franchises
select distinct * from "transformed"."franchises";
create table if not exists "teamseasons" (
"year" NUMERIC,
"league" TEXT,
"team" TEXT,
"division" TEXT,
"Rank" NUMERIC,
"G" NUMERIC,
"Ghome" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
"DivWin" NUMERIC,
"WCWin" NUMERIC,
"LgWin" NUMERIC,
"WSWin" NUMERIC,
"R" NUMERIC,
"AB" NUMERIC,
"H" NUMERIC,
"2B" NUMERIC,
"3B" NUMERIC,
"HR" NUMERIC,
"BB" NUMERIC,
"SO" NUMERIC,
"SB" NUMERIC,
"CS" NUMERIC,
"HBP" NUMERIC,
"SF" NUMERIC,
"RA" NUMERIC,
"ER" NUMERIC,
"ERA" NUMERIC,
"CG" NUMERIC,
"SHO" NUMERIC,
"SV" NUMERIC,
"IPouts" NUMERIC,
"HA" NUMERIC,
"HRA" NUMERIC,
"BBA" NUMERIC,
"SOA" NUMERIC,
"E" NUMERIC,
"DP" NUMERIC,
"FP" NUMERIC,
"name" NUMERIC,
"park" NUMERIC,
"attendance" NUMERIC,
"BPF" NUMERIC,
"PPF" NUMERIC,
"teamIDBR" TEXT,
"teamIDlahman45" TEXT,
"teamIDretro" TEXT,
PRIMARY KEY("year","team"),
foreign key("year") references "seasons"("year"),
foreign key("league") references "leagues"("ID"),
foreign key("team") references "teams"("ID")
);
insert into teamseasons
select distinct * from "transformed"."teamseasons";
create table if not exists "seasons" (
"year" numeric,
primary key("year")
);
insert into seasons
select distinct * from "transformed"."seasons";
CREATE TABLE "people" (
"ID" text,
"birthYear" NUMERIC,
"birthMonth" NUMERIC,
"birthDay" NUMERIC,
"birthCountry" text,
"birthState" text,
"birthCity" text,
"deathYear" text,
"deathMonth" text,
"deathDay" text,
"deathCountry" text,
"deathState" text,
"deathCity" text,
"nameFirst" text,
"nameLast" text,
"nameGiven" text,
"weight" NUMERIC,
"height" NUMERIC,
"bats" text,
"throws" text,
"debut" text,
"finalGame" text,
"retroID" text,
"bbrefID" text,
primary key("ID")
);
INSERT INTO "people" SELECT DISTINCT * FROM "transformed"."people";
CREATE TABLE IF NOT EXISTS "parks" (
"ID" TEXT,
"name" TEXT,
"city" TEXT,
"state" TEXT,
"country" TEXT,
PRIMARY KEY("ID")
);
insert into "parks" select distinct * from "transformed"."parks";
CREATE TABLE IF NOT EXISTS "parkaliases" (
"park" TEXT,
"alias" TEXT,
PRIMARY KEY("park","alias"),
foreign key("park") references "parks"("ID")
);
insert into "parkaliases" select distinct * from "transformed"."parkaliases";
CREATE TABLE IF NOT EXISTS "collegeplaying" (
"player" TEXT,
"school" TEXT,
"year" NUMERIC,
PRIMARY KEY("player","year","school"),
foreign key("player") references "people"("ID"),
foreign key("school") references "schools"("ID")
);
insert into collegeplaying select distinct * from "transformed"."collegeplaying";
CREATE TABLE IF NOT EXISTS "schools" (
"ID" TEXT,
"name_full" TEXT,
"city" TEXT,
"state" TEXT,
"country" TEXT,
PRIMARY KEY("ID")
);
insert into schools select distinct * from "transformed"."schools";
CREATE TABLE IF NOT EXISTS "salaries" (
"year" NUMERIC,
"team" TEXT,
"player" TEXT,
"salary" NUMERIC,
PRIMARY KEY("year","player","team"),
foreign key("player") references "people"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into salaries select distinct * from "transformed"."salaries";
CREATE TABLE IF NOT EXISTS "batting" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"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("player","year","stint"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into batting select distinct * from "transformed"."batting";
CREATE TABLE IF NOT EXISTS "fielding" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"POS" TEXT,
"G" NUMERIC,
"GS" NUMERIC,
"InnOuts" NUMERIC,
"PO" NUMERIC,
"A" NUMERIC,
"E" NUMERIC,
"DP" NUMERIC,
"PB" NUMERIC,
"WP" NUMERIC,
"SB" NUMERIC,
"CS" NUMERIC,
"ZR" NUMERIC,
PRIMARY KEY("player","year","stint","POS"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into fielding select distinct * from "transformed"."fielding";
CREATE TABLE IF NOT EXISTS "pitching" (
"player" TEXT,
"year" NUMERIC,
"stint" 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","stint"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into pitching select distinct * from "transformed"."pitching";
CREATE TABLE IF NOT EXISTS "appearances" (
"year" NUMERIC,
"team" TEXT,
"player" TEXT,
"G_all" NUMERIC,
"GS" NUMERIC,
"G_batting" NUMERIC,
"G_defense" NUMERIC,
"G_p" NUMERIC,
"G_c" NUMERIC,
"G_1b" NUMERIC,
"G_2b" NUMERIC,
"G_3b" NUMERIC,
"G_ss" NUMERIC,
"G_lf" NUMERIC,
"G_cf" NUMERIC,
"G_rf" NUMERIC,
"G_of" NUMERIC,
"G_dh" NUMERIC,
"G_ph" NUMERIC,
"G_pr" NUMERIC,
PRIMARY KEY("year","team","player"),
foreign key("player") references "people"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into appearances select distinct * from "transformed"."appearances";
CREATE TABLE IF NOT EXISTS "homegames" (
"year" NUMERIC,
"team" TEXT,
"park" TEXT,
"first" TEXT,
"last" TEXT,
"games" NUMERIC,
"openings" NUMERIC,
"attendance" NUMERIC,
PRIMARY KEY("year","team","park"),
foreign key("park") references "parks"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into homegames select distinct * from "transformed"."homegames";
CREATE TABLE IF NOT EXISTS "seriespost" (
"year" NUMERIC,
"round" NUMERIC,
"winner" TEXT,
"loser" TEXT,
"wins" NUMERIC,
"losses" NUMERIC,
"ties" NUMERIC,
PRIMARY KEY("year","round"),
foreign key("year") references "seasons"("year"),
foreign key("winner") references "teams"("ID"),
foreign key("loser") references "teams"("ID")
);
insert into seriespost select distinct * from "transformed"."seriespost";
CREATE TABLE IF NOT EXISTS "fieldingofsplit" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"POS" TEXT,
"G" NUMERIC,
"GS" NUMERIC,
"InnOuts" NUMERIC,
"PO" NUMERIC,
"A" NUMERIC,
"E" NUMERIC,
"DP" NUMERIC,
"PB" NUMERIC,
"WP" NUMERIC,
"SB" NUMERIC,
"CS" NUMERIC,
"ZR" NUMERIC,
PRIMARY KEY("player","year","stint","POS"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into fieldingofsplit select distinct * from "transformed"."fieldingofsplit";
create table if not exists teams (
"ID" text,
"franchise" text,
primary key("ID"),
foreign key("franchise") references "franchises"("ID")
);
insert into teams select distinct * from "transformed"."teams";
create table if not exists "leagues" (
"ID" text,
"name" text,
primary key("ID")
);
insert into leagues select distinct * from "transformed"."leagues";
CREATE TABLE IF NOT EXISTS "managers" (
"ID" TEXT,
"year" NUMERIC,
"team" TEXT,
"inseason" NUMERIC,
"G" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
"plyrMgr" TEXT,
PRIMARY KEY("ID","year","team","inseason"),
foreign key("ID") references "people"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into managers select distinct * from "transformed"."managers";
CREATE TABLE IF NOT EXISTS "awardsmanagers" (
"manager" TEXT,
"award" TEXT,
"year" NUMERIC,
"league" TEXT,
"notes" TEXT,
PRIMARY KEY("manager","award","year","league"),
foreign key("manager") references "people"("ID"),
foreign key("award","year","league") references "yearlyawards"("award","year","league")
);
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","year") references "appearancespost"("player","year"),
foreign key("year","round") references "seriespost"("year","round")
);
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","year") references "appearancespost"("player","year"),
foreign key("year","round") references "seriespost"("year","round")
);
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","year") references "appearancespost"("player","year"),
foreign key("year","round") references "seriespost"("year","round")
);
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";
CREATE TABLE IF NOT EXISTS "fieldingof" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"Glf" NUMERIC,
"Gcf" NUMERIC,
"Grf" NUMERIC,
PRIMARY KEY("player","year","stint"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into fieldingof select distinct * from "transformed"."fieldingof";
CREATE TABLE IF NOT EXISTS "awardssharemanagers" (
"award" TEXT,
"year" NUMERIC,
"league" TEXT,
"manager" TEXT,
"pointsWon" NUMERIC,
"pointsMax" NUMERIC,
"votesFirst" NUMERIC,
PRIMARY KEY("manager","award","year","league"),
foreign key("manager") references "people"("ID"),
foreign key("award","year","league") references "yearlyawards"("award","year","league")
);
insert into awardssharemanagers select distinct * from "transformed"."awardssharemanagers";
CREATE TABLE IF NOT EXISTS "awardsshareplayers" (
"award" TEXT,
"year" NUMERIC,
"league" TEXT,
"player" TEXT,
"pointsWon" NUMERIC,
"pointsMax" NUMERIC,
"votesFirst" NUMERIC,
PRIMARY KEY("award","year","player","league"),
foreign key("player") references "people"("ID"),
foreign key("award","year","league") references "yearlyawards"("award","year","league")
);
insert into awardsshareplayers select distinct * from "transformed"."awardsshareplayers";
create table if not exists "yearlyawards" (
"year" numeric,
"award" text,
"league" text,
primary key("year","award","league"),
foreign key("year") references "seasons"("year"),
foreign key("award") references "awards"("ID")
);
insert into yearlyawards select distinct * from "transformed"."yearlyawards";
CREATE TABLE IF NOT EXISTS "halloffame" (
"player" TEXT,
"year" NUMERIC,
"votedBy" TEXT,
"votes" NUMERIC,
"inducted" TEXT,
"category" TEXT,
PRIMARY KEY("player","year","votedBy")
foreign key("player") references "people"("ID"),
foreign key("year","votedBy") references "halloffamereqs"("year","votedBy")
);
insert into halloffame select distinct * from "transformed".halloffame;
create table if not exists "halloffamereqs" (
"year" numeric,
"votedBy" text,
"ballots" numeric,
"needed" numeric,
"needed_note" text,
primary key("year","votedBy"),
foreign key("year") references "seasons"("year")
);
insert into halloffamereqs select distinct * from "transformed".halloffamereqs;
CREATE TABLE IF NOT EXISTS "awardsplayers" (
"player" TEXT,
"award" TEXT,
"year" NUMERIC,
"league" TEXT,
"notes" TEXT,
PRIMARY KEY("award","year","league","notes","player"),
foreign key("player") references "people"("ID"),
foreign key("award","year","league") references "yearlyawards"("award","year","league")
);
insert into awardsplayers select distinct * from "transformed".awardsplayers;
CREATE TABLE IF NOT EXISTS "teamseasonshalf" (
"year" NUMERIC,
"team" TEXT,
"Half" NUMERIC,
"Rank" NUMERIC,
"G" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
PRIMARY KEY("year","team","Half"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into teamseasonshalf select distinct * from "transformed".teamseasonshalf;
CREATE TABLE IF NOT EXISTS "managershalf" (
"ID" TEXT,
"year" NUMERIC,
"team" TEXT,
"inseason" NUMERIC,
"half" NUMERIC,
"G" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
PRIMARY KEY("ID","year","team","inseason","half"),
foreign key("ID","year","team","inseason") references "managers"("ID","year","team","inseason")
);
insert into managershalf select distinct * from "transformed".managershalf;
CREATE TABLE "allstarstartingpos" (
"player" NUMERIC,
"year" NUMERIC,
"gameNum" NUMERIC,
"league" NUMERIC,
"startingPos" NUMERIC,
primary key("year","gameNum","league","startingPos"),
foreign key("player","year","gameNum") references "allstars"("player","year","gameNum"),
foreign key("league") references "leagues"("ID")
);
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;
create table if not exists "playerstints" (
"player" text,
"year" numeric,
"stint" numeric,
"team" text,
primary key("player","year","stint"),
foreign key("player","year","team") references "appearances"("player","year","team")
);
insert into playerstints select distinct * from "transformed".playerstints;
COMMIT;

View File

@ -1,4 +1,9 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table managers as
select * from "raw".managers;
alter table managers drop column "lgID";
alter table managers drop column "rank";
@ -9,4 +14,20 @@ where teamid = 'WAS' and yearid between 1891 and 1899;
update managers
set teamid = 'PHP'
where teamid = 'PH4' and yearid between 1890 and 1891;
CREATE TABLE IF NOT EXISTS main."managers" (
"ID" TEXT,
"year" NUMERIC,
"team" TEXT,
"inseason" NUMERIC,
"G" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
"plyrMgr" TEXT,
PRIMARY KEY("ID","year","team","inseason"),
foreign key("ID") references "people"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into main.managers select distinct * from temp."managers";
commit;

View File

@ -1,8 +1,28 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table managershalf as
select * from "raw".managershalf;
alter table managershalf drop column "lgID";
alter table managershalf drop column "rank";
update managershalf
set teamid = 'WS9'
where yearid = 1892 and teamid = 'WAS';
CREATE TABLE IF NOT EXISTS main."managershalf" (
"ID" TEXT,
"year" NUMERIC,
"team" TEXT,
"inseason" NUMERIC,
"half" NUMERIC,
"G" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
PRIMARY KEY("ID","year","team","inseason","half"),
foreign key("ID","year","team","inseason") references "managers"("ID","year","team","inseason")
);
insert into main.managershalf select distinct * from temp.managershalf;
commit;

View File

@ -1,7 +1,7 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create table if not exists "parkaliases" (
create temp table if not exists "parkaliases" (
"parkID" text,
"alias" text
);
@ -19,4 +19,13 @@ select parkid, case instr(alias, ";")
else trim(substr(alias, 1, instr(alias, ";") - 1)) end as a
from aliases
where a != '';
CREATE TABLE IF NOT EXISTS main."parkaliases" (
"park" TEXT,
"alias" TEXT,
PRIMARY KEY("park","alias"),
foreign key("park") references "parks"("ID")
);
insert into main."parkaliases" select distinct * from temp."parkaliases";
commit;

View File

@ -1,4 +1,9 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table parks as
select * from "raw".parks;
alter table parks drop column "park.alias";
-- insert some missing parks
@ -7,4 +12,15 @@ insert into parks values
('BUF05', 'Sahlen Field', 'Buffalo', 'NY', 'US'),
('DUN01', 'TD Ballpark', 'Dunedin', 'FL', 'US'),
('DYE01', 'Field of Dreams', 'Dyersville', 'IA', 'US');
CREATE TABLE IF NOT EXISTS main."parks" (
"ID" TEXT,
"name" TEXT,
"city" TEXT,
"state" TEXT,
"country" TEXT,
PRIMARY KEY("ID")
);
insert into main.parks select distinct * from temp."parks";
commit;

View File

@ -1,7 +1,42 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table people as
select * from "raw".people;
-- insert some missing people
insert into people values
('millema99', 1917, 4, 14, 'USA', 'NY', 'Brooklyn', 2012, 11, 27, 'USA', 'NY', 'Manhattan', 'Marvin', 'Miller', 'Marvin Julian', null, null, null, null, null, null, null, 'millema99'),
('fowlebu99', 1858, 3, 16, 'USA', 'NY', 'Fort Plain', 1913, 2, 26, 'USA', 'NY', 'Frankfort', 'Bud', 'Fowler', 'John W. Jackson', 155, 67, 'R', 'R', null, null, null, 'fowlebu99'),
('thompan01', null, null, null, null, null, null, null, null, null, null, null, null, null, 'Thompson', null, null, null, null, null, '1875-04-26', '1875-05-17', null, 'thompan01');
CREATE TABLE main."people" (
"ID" text,
"birthYear" NUMERIC,
"birthMonth" NUMERIC,
"birthDay" NUMERIC,
"birthCountry" text,
"birthState" text,
"birthCity" text,
"deathYear" text,
"deathMonth" text,
"deathDay" text,
"deathCountry" text,
"deathState" text,
"deathCity" text,
"nameFirst" text,
"nameLast" text,
"nameGiven" text,
"weight" NUMERIC,
"height" NUMERIC,
"bats" text,
"throws" text,
"debut" text,
"finalGame" text,
"retroID" text,
"bbrefID" text,
primary key("ID")
);
INSERT INTO main."people" SELECT DISTINCT * FROM temp."people";
commit;

View File

@ -1,4 +1,44 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table pitching as
select * from "raw".pitching;
alter table pitching drop column "lgID";
alter table pitching drop column "teamID";
CREATE TABLE IF NOT EXISTS main."pitching" (
"player" TEXT,
"year" NUMERIC,
"stint" 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","stint"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into main.pitching select distinct * from temp."pitching";
commit;

View File

@ -1,4 +1,45 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table pitchingpost as
select * from "raw".pitchingpost;
alter table pitchingpost drop column "lgID";
alter table pitchingpost drop column "teamID";
CREATE TABLE IF NOT EXISTS main."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","year") references "appearancespost"("player","year"),
foreign key("year","round") references "seriespost"("year","round")
);
insert into main.pitchingpost select distinct * from temp."pitchingpost";
commit;

View File

@ -1,7 +1,7 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create table if not exists "playerstints" (
create temp table if not exists "playerstints" (
"player" text,
"year" numeric,
"stint" numeric,
@ -25,4 +25,15 @@ where team = 'WAS' and year between 1891 and 1899;
update playerstints
set team = 'PHP'
where team = 'PH4' and year between 1890 and 1891;
create table if not exists main."playerstints" (
"player" text,
"year" numeric,
"stint" numeric,
"team" text,
primary key("player","year","stint"),
foreign key("player","year","team") references "appearances"("player","year","team")
);
insert into main.playerstints select distinct * from temp.playerstints;
commit;

View File

@ -1,3 +1,20 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table salaries as
select * from "raw".salaries;
alter table "salaries" drop column "lgID";
CREATE TABLE IF NOT EXISTS main."salaries" (
"year" NUMERIC,
"team" TEXT,
"player" TEXT,
"salary" NUMERIC,
PRIMARY KEY("year","player","team"),
foreign key("player") references "people"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into main.salaries select distinct * from temp."salaries";
commit;

View File

@ -1,6 +1,22 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table schools as
select * from "raw".schools;
-- insert some missing schools
insert into schools values
('txutper', 'University of Texas Permian Basin', 'Odessa', 'TX', 'USA'),
('txrange', 'Ranger College', 'Ranger', 'TX', 'USA');
CREATE TABLE IF NOT EXISTS main."schools" (
"ID" TEXT,
"name_full" TEXT,
"city" TEXT,
"state" TEXT,
"country" TEXT,
PRIMARY KEY("ID")
);
insert into main.schools select distinct * from temp."schools";
commit;

View File

@ -1,7 +1,16 @@
begin;
create table if not exists "seasons" (
attach database 'baseball-raw.db' as 'raw';
create temp table if not exists "seasons" (
"year" text
);
insert into seasons select distinct yearID from appearances;
insert into seasons select distinct yearID from "raw".appearances;
create table if not exists main."seasons" (
"year" numeric,
primary key("year")
);
insert into main.seasons
select distinct * from temp."seasons";
commit;

View File

@ -1,4 +1,25 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table seriespost as
select * from "raw".seriespost;
alter table "seriespost" drop column "lgIDwinner";
alter table "seriespost" drop column "lgIDloser";
CREATE TABLE IF NOT EXISTS main."seriespost" (
"year" NUMERIC,
"round" NUMERIC,
"winner" TEXT,
"loser" TEXT,
"wins" NUMERIC,
"losses" NUMERIC,
"ties" NUMERIC,
PRIMARY KEY("year","round"),
foreign key("year") references "seasons"("year"),
foreign key("winner") references "teams"("ID"),
foreign key("loser") references "teams"("ID")
);
insert into main.seriespost select distinct * from temp."seriespost";
commit;

View File

@ -1,6 +1,6 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create table if not exists teams (
create temp table if not exists teams (
"ID" text,
"franchise" text
);
@ -15,4 +15,13 @@ where ID = 'WAS' and franchise = 'WAS';
update teams
set ID = 'PHP'
where ID = 'PH4' and franchise = 'PHQ';
create table if not exists main.teams (
"ID" text,
"franchise" text,
primary key("ID"),
foreign key("franchise") references "franchises"("ID")
);
insert into main.teams select distinct * from temp."teams";
commit;

View File

@ -1,5 +1,8 @@
begin;
alter table "teams" rename to "teamseasons";
attach database 'baseball-raw.db' as 'raw';
create temp table teamseasons as
select * from teams;
update teamseasons
set teamid = 'WS9'
@ -10,4 +13,61 @@ set teamid = 'PHP'
where teamid = 'PH4' and franchid = 'PHQ';
alter table "teamseasons" drop column "franchID";
create table if not exists main."teamseasons" (
"year" NUMERIC,
"league" TEXT,
"team" TEXT,
"division" TEXT,
"Rank" NUMERIC,
"G" NUMERIC,
"Ghome" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
"DivWin" NUMERIC,
"WCWin" NUMERIC,
"LgWin" NUMERIC,
"WSWin" NUMERIC,
"R" NUMERIC,
"AB" NUMERIC,
"H" NUMERIC,
"2B" NUMERIC,
"3B" NUMERIC,
"HR" NUMERIC,
"BB" NUMERIC,
"SO" NUMERIC,
"SB" NUMERIC,
"CS" NUMERIC,
"HBP" NUMERIC,
"SF" NUMERIC,
"RA" NUMERIC,
"ER" NUMERIC,
"ERA" NUMERIC,
"CG" NUMERIC,
"SHO" NUMERIC,
"SV" NUMERIC,
"IPouts" NUMERIC,
"HA" NUMERIC,
"HRA" NUMERIC,
"BBA" NUMERIC,
"SOA" NUMERIC,
"E" NUMERIC,
"DP" NUMERIC,
"FP" NUMERIC,
"name" NUMERIC,
"park" NUMERIC,
"attendance" NUMERIC,
"BPF" NUMERIC,
"PPF" NUMERIC,
"teamIDBR" TEXT,
"teamIDlahman45" TEXT,
"teamIDretro" TEXT,
PRIMARY KEY("year","team"),
foreign key("year") references "seasons"("year"),
foreign key("league") references "leagues"("ID"),
foreign key("team") references "teams"("ID")
);
insert into main.teamseasons
select distinct * from temp."teamseasons";
commit;

View File

@ -1,7 +1,8 @@
begin;
attach database 'baseball-raw.db' as 'raw';
alter table teamshalf rename to "teamseasonshalf";
create temp table teamseasonshalf as
select * from "raw".teamshalf;
alter table teamseasonshalf drop column "lgID";
alter table teamseasonshalf drop column "divID";
@ -17,4 +18,17 @@ update teamseasonshalf
set teamid = 'WS9'
where yearid = 1892 and teamid = 'WAS';
CREATE TABLE IF NOT EXISTS main."teamseasonshalf" (
"year" NUMERIC,
"team" TEXT,
"Half" NUMERIC,
"Rank" NUMERIC,
"G" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
PRIMARY KEY("year","team","Half"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into main.teamseasonshalf select distinct * from temp.teamseasonshalf;
commit;

View File

@ -1,6 +1,6 @@
begin;
attach database 'baseball-raw.db' as 'raw';
create table if not exists "yearlyawards" (
create temp table if not exists "yearlyawards" (
"year" numeric,
"award" text,
"league" text
@ -12,4 +12,15 @@ from "raw".awardsmanagers
union
select distinct yearid, awardid, lgID
from "raw".awardsplayers;
create table if not exists main."yearlyawards" (
"year" numeric,
"award" text,
"league" text,
primary key("year","award","league"),
foreign key("year") references "seasons"("year"),
foreign key("award") references "awards"("ID")
);
insert into main.yearlyawards select distinct * from temp."yearlyawards";
commit;