add schools table
This commit is contained in:
parent
7ed54099e4
commit
def464ce0a
3
Makefile
3
Makefile
|
@ -9,7 +9,7 @@ baseball.db: baseball-transformed.db sql/load.sql
|
||||||
cat sql/load.sql | sqlite3 baseball.db
|
cat sql/load.sql | sqlite3 baseball.db
|
||||||
sqlite3 baseball.db "VACUUM"
|
sqlite3 baseball.db "VACUUM"
|
||||||
|
|
||||||
baseball-transformed.db: baseball-raw.db sql/awards.sql sql/franchises.sql sql/franchiseseasons.sql sql/seasons.sql sql/parks.sql sql/collegeplaying.sql
|
baseball-transformed.db: baseball-raw.db sql/awards.sql sql/franchises.sql sql/franchiseseasons.sql sql/seasons.sql sql/parks.sql sql/collegeplaying.sql sql/schools.sql
|
||||||
rm -f baseball-transformed.db
|
rm -f baseball-transformed.db
|
||||||
cp baseball-raw.db baseball-transformed.db
|
cp baseball-raw.db baseball-transformed.db
|
||||||
cat sql/franchises.sql | sqlite3 baseball-transformed.db
|
cat sql/franchises.sql | sqlite3 baseball-transformed.db
|
||||||
|
@ -18,6 +18,7 @@ baseball-transformed.db: baseball-raw.db sql/awards.sql sql/franchises.sql sql/f
|
||||||
cat sql/seasons.sql | sqlite3 baseball-transformed.db
|
cat sql/seasons.sql | sqlite3 baseball-transformed.db
|
||||||
cat sql/parks.sql | sqlite3 baseball-transformed.db
|
cat sql/parks.sql | sqlite3 baseball-transformed.db
|
||||||
cat sql/collegeplaying.sql | sqlite3 baseball-transformed.db
|
cat sql/collegeplaying.sql | sqlite3 baseball-transformed.db
|
||||||
|
cat sql/schools.sql | sqlite3 baseball-transformed.db
|
||||||
|
|
||||||
baseball-raw.db:
|
baseball-raw.db:
|
||||||
rm -f baseball-raw.db
|
rm -f baseball-raw.db
|
||||||
|
|
61
sql/load.sql
61
sql/load.sql
|
@ -10,22 +10,22 @@ insert into awards
|
||||||
select distinct * from "transformed"."awards";
|
select distinct * from "transformed"."awards";
|
||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS "franchises" (
|
CREATE TABLE IF NOT EXISTS "franchises" (
|
||||||
"franchID" TEXT,
|
"ID" TEXT,
|
||||||
"franchName" TEXT,
|
"name" TEXT,
|
||||||
"active" TEXT,
|
"active" TEXT,
|
||||||
"NAassoc" TEXT,
|
"NAassoc" TEXT,
|
||||||
PRIMARY KEY("franchID")
|
PRIMARY KEY("ID")
|
||||||
);
|
);
|
||||||
|
|
||||||
insert into franchises
|
insert into franchises
|
||||||
select distinct * from "transformed"."franchises";
|
select distinct * from "transformed"."franchises";
|
||||||
|
|
||||||
create table if not exists "franchiseseasons" (
|
create table if not exists "franchiseseasons" (
|
||||||
"yearID" NUMERIC,
|
"year" NUMERIC,
|
||||||
"lgID" TEXT,
|
"league" TEXT,
|
||||||
"teamID" TEXT,
|
"team" TEXT,
|
||||||
"franchID" TEXT,
|
"franchise" TEXT,
|
||||||
"divID" TEXT,
|
"division" TEXT,
|
||||||
"Rank" NUMERIC,
|
"Rank" NUMERIC,
|
||||||
"G" NUMERIC,
|
"G" NUMERIC,
|
||||||
"Ghome" NUMERIC,
|
"Ghome" NUMERIC,
|
||||||
|
@ -69,9 +69,9 @@ create table if not exists "franchiseseasons" (
|
||||||
"teamIDBR" TEXT,
|
"teamIDBR" TEXT,
|
||||||
"teamIDlahman45" TEXT,
|
"teamIDlahman45" TEXT,
|
||||||
"teamIDretro" TEXT,
|
"teamIDretro" TEXT,
|
||||||
PRIMARY KEY("yearID","franchID"),
|
PRIMARY KEY("year","franchise"),
|
||||||
foreign key("yearID") references "seasons"("year"),
|
foreign key("year") references "seasons"("year"),
|
||||||
foreign key("franchID") references "franchises"("ID")
|
foreign key("franchise") references "franchises"("ID")
|
||||||
);
|
);
|
||||||
|
|
||||||
insert into franchiseseasons
|
insert into franchiseseasons
|
||||||
|
@ -86,7 +86,7 @@ insert into seasons
|
||||||
select distinct * from "transformed"."seasons";
|
select distinct * from "transformed"."seasons";
|
||||||
|
|
||||||
CREATE TABLE "people" (
|
CREATE TABLE "people" (
|
||||||
"playerID" text,
|
"ID" text,
|
||||||
"birthYear" NUMERIC,
|
"birthYear" NUMERIC,
|
||||||
"birthMonth" NUMERIC,
|
"birthMonth" NUMERIC,
|
||||||
"birthDay" NUMERIC,
|
"birthDay" NUMERIC,
|
||||||
|
@ -110,39 +110,50 @@ CREATE TABLE "people" (
|
||||||
"finalGame" text,
|
"finalGame" text,
|
||||||
"retroID" text,
|
"retroID" text,
|
||||||
"bbrefID" text,
|
"bbrefID" text,
|
||||||
primary key("playerID")
|
primary key("ID")
|
||||||
);
|
);
|
||||||
|
|
||||||
INSERT INTO "people" SELECT DISTINCT * FROM "transformed"."people";
|
INSERT INTO "people" SELECT DISTINCT * FROM "transformed"."people";
|
||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS "parks" (
|
CREATE TABLE IF NOT EXISTS "parks" (
|
||||||
"park.key" TEXT,
|
"ID" TEXT,
|
||||||
"park.name" TEXT,
|
"name" TEXT,
|
||||||
"city" TEXT,
|
"city" TEXT,
|
||||||
"state" TEXT,
|
"state" TEXT,
|
||||||
"country" TEXT,
|
"country" TEXT,
|
||||||
PRIMARY KEY("park.key")
|
PRIMARY KEY("ID")
|
||||||
);
|
);
|
||||||
|
|
||||||
insert into "parks" select distinct * from "transformed"."parks";
|
insert into "parks" select distinct * from "transformed"."parks";
|
||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS "parkaliases" (
|
CREATE TABLE IF NOT EXISTS "parkaliases" (
|
||||||
"ID" TEXT,
|
"park" TEXT,
|
||||||
"alias" TEXT,
|
"alias" TEXT,
|
||||||
PRIMARY KEY("ID","alias"),
|
PRIMARY KEY("park","alias"),
|
||||||
foreign key("ID") references "parks"("park.key")
|
foreign key("park") references "parks"("ID")
|
||||||
);
|
);
|
||||||
|
|
||||||
insert into "parkaliases" select distinct * from "transformed"."parkaliases";
|
insert into "parkaliases" select distinct * from "transformed"."parkaliases";
|
||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS "collegeplaying" (
|
CREATE TABLE IF NOT EXISTS "collegeplaying" (
|
||||||
"playerID" TEXT,
|
"player" TEXT,
|
||||||
"schoolID" TEXT,
|
"school" TEXT,
|
||||||
"yearID" NUMERIC,
|
"year" NUMERIC,
|
||||||
PRIMARY KEY("playerID","yearID","schoolID"),
|
PRIMARY KEY("player","year","school"),
|
||||||
foreign key("playerID") references "people"("playerID"),
|
foreign key("player") references "people"("ID"),
|
||||||
foreign key("schoolID") references "schools"("schoolID")
|
foreign key("school") references "schools"("ID")
|
||||||
);
|
);
|
||||||
|
|
||||||
insert into collegeplaying select distinct * from "transformed"."collegeplaying";
|
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";
|
||||||
COMMIT;
|
COMMIT;
|
||||||
|
|
Loading…
Reference in New Issue