From f1bb5512bfc9500b6a3c54c9c41ef7e713403d6b Mon Sep 17 00:00:00 2001 From: Nick Griffey Date: Sat, 27 Jan 2024 18:05:45 -0600 Subject: [PATCH] restructure some more --- Makefile | 13 ++++- sql/awards.sql | 13 +++++ sql/franchises.sql | 16 +----- sql/franchiseseasons.sql | 3 + sql/load.sql | 117 +++++++++++++++++++++++++++++++++++++++ sql/people.sql | 32 ----------- sql/seasons.sql | 5 ++ 7 files changed, 151 insertions(+), 48 deletions(-) create mode 100644 sql/awards.sql create mode 100644 sql/franchiseseasons.sql create mode 100644 sql/load.sql delete mode 100644 sql/people.sql create mode 100644 sql/seasons.sql diff --git a/Makefile b/Makefile index 075ed46..a5ef9de 100644 --- a/Makefile +++ b/Makefile @@ -4,12 +4,19 @@ bbdb = baseballdatabank-2023.1 db: baseball.db -baseball.db: baseball-raw.db sql/people.sql sql/franchises.sql +baseball.db: baseball-transformed.db sql/load.sql rm -f baseball.db - cat sql/people.sql | sqlite3 baseball.db - cat sql/franchises.sql | sqlite3 baseball.db + cat sql/load.sql | sqlite3 baseball.db sqlite3 baseball.db "VACUUM" +baseball-transformed.db: baseball-raw.db sql/awards.sql sql/franchises.sql sql/franchiseseasons.sql sql/seasons.sql + rm -f baseball-transformed.db + cp baseball-raw.db baseball-transformed.db + cat sql/franchises.sql | sqlite3 baseball-transformed.db + cat sql/franchiseseasons.sql | sqlite3 baseball-transformed.db + cat sql/awards.sql | sqlite3 baseball-transformed.db + cat sql/seasons.sql | sqlite3 baseball-transformed.db + baseball-raw.db: rm -f baseball-raw.db sqlite3 baseball-raw.db ".import --csv $(bbdb)/core/AllstarFull.csv allstarfull" diff --git a/sql/awards.sql b/sql/awards.sql new file mode 100644 index 0000000..5000d6d --- /dev/null +++ b/sql/awards.sql @@ -0,0 +1,13 @@ +begin; +attach database 'baseball-raw.db' as 'raw'; +create table if not exists "awards" ( + "ID" text +); + +insert into awards +select distinct awardID +from "raw".awardsmanagers +union +select distinct awardID +from "raw".awardsplayers; +commit; diff --git a/sql/franchises.sql b/sql/franchises.sql index ac3f378..03e5951 100644 --- a/sql/franchises.sql +++ b/sql/franchises.sql @@ -1,13 +1,3 @@ -BEGIN; -attach database 'baseball-raw.db' as 'raw'; -CREATE TABLE IF NOT EXISTS "franchises" ( - "franchID" TEXT, - "franchName" TEXT, - "active" TEXT, - "NAassoc" TEXT, - PRIMARY KEY("franchID") -); - -insert into franchises -select distinct * from 'raw'.'teamsfranchises'; -COMMIT; +begin; +alter table "teamsfranchises" rename to "franchises"; +commit; diff --git a/sql/franchiseseasons.sql b/sql/franchiseseasons.sql new file mode 100644 index 0000000..08e492d --- /dev/null +++ b/sql/franchiseseasons.sql @@ -0,0 +1,3 @@ +begin; +alter table "teams" rename to "franchiseseasons"; +commit; diff --git a/sql/load.sql b/sql/load.sql new file mode 100644 index 0000000..902d64c --- /dev/null +++ b/sql/load.sql @@ -0,0 +1,117 @@ +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" ( + "franchID" TEXT, + "franchName" TEXT, + "active" TEXT, + "NAassoc" TEXT, + PRIMARY KEY("franchID") +); + +insert into franchises +select distinct * from "transformed"."franchises"; + +create table if not exists "franchiseseasons" ( + "yearID" NUMERIC, + "lgID" TEXT, + "teamID" TEXT, + "franchID" TEXT, + "divID" 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("yearID","franchID"), + foreign key("yearID") references "seasons"("year"), + foreign key("franchID") references "franchises"("ID") +); + +insert into franchiseseasons +select distinct * from "transformed"."franchiseseasons"; + +create table if not exists "seasons" ( + "year" numeric, + primary key("year") +); + +insert into seasons +select distinct * from "transformed"."seasons"; + +CREATE TABLE "people" ( + "playerID" 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("playerID") +); + +INSERT INTO "people" SELECT DISTINCT * FROM "transformed"."people"; +COMMIT; diff --git a/sql/people.sql b/sql/people.sql deleted file mode 100644 index 326bf30..0000000 --- a/sql/people.sql +++ /dev/null @@ -1,32 +0,0 @@ -BEGIN; -attach database 'baseball-raw.db' as 'raw'; -CREATE TABLE "people" ( - "playerID" 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("playerID") -); - -INSERT INTO "people" SELECT DISTINCT * FROM "raw"."people"; -COMMIT; diff --git a/sql/seasons.sql b/sql/seasons.sql new file mode 100644 index 0000000..69b6edd --- /dev/null +++ b/sql/seasons.sql @@ -0,0 +1,5 @@ +begin; +create table if not exists "seasons" ( + "year" text +); +commit;