lahmanlite/sql/load.sql

647 lines
15 KiB
PL/PgSQL

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,
"team" 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("player","year","stint","team"),
foreign key("year","player","team") references "appearances"("year","player","team")
);
insert into batting select distinct * from "transformed"."batting";
CREATE TABLE IF NOT EXISTS "fielding" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"team" TEXT,
"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","team","POS"),
foreign key("year","player","team") references "appearances"("year","player","team")
);
insert into fielding select distinct * from "transformed"."fielding";
CREATE TABLE IF NOT EXISTS "pitching" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"team" 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("player","year","stint","team"),
foreign key("year","player","team") references "appearances"("year","player","team")
);
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,
"team" TEXT,
"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","team","POS"),
foreign key("year","player","team") references "appearances"("year","player","team")
);
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") 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";
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("player") references "people"("ID"),
foreign key("year") references "seasons"("year")
);
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,
"DivWin" TEXT,
"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") references "people"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
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;