restructure some more

This commit is contained in:
Nick Griffey 2024-01-27 18:05:45 -06:00
parent 6cc8f3aa3d
commit f1bb5512bf
7 changed files with 151 additions and 48 deletions

View File

@ -4,12 +4,19 @@ bbdb = baseballdatabank-2023.1
db: baseball.db 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 rm -f baseball.db
cat sql/people.sql | sqlite3 baseball.db cat sql/load.sql | sqlite3 baseball.db
cat sql/franchises.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
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: baseball-raw.db:
rm -f baseball-raw.db rm -f baseball-raw.db
sqlite3 baseball-raw.db ".import --csv $(bbdb)/core/AllstarFull.csv allstarfull" sqlite3 baseball-raw.db ".import --csv $(bbdb)/core/AllstarFull.csv allstarfull"

13
sql/awards.sql Normal file
View File

@ -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;

View File

@ -1,13 +1,3 @@
BEGIN; begin;
attach database 'baseball-raw.db' as 'raw'; alter table "teamsfranchises" rename to "franchises";
CREATE TABLE IF NOT EXISTS "franchises" ( commit;
"franchID" TEXT,
"franchName" TEXT,
"active" TEXT,
"NAassoc" TEXT,
PRIMARY KEY("franchID")
);
insert into franchises
select distinct * from 'raw'.'teamsfranchises';
COMMIT;

3
sql/franchiseseasons.sql Normal file
View File

@ -0,0 +1,3 @@
begin;
alter table "teams" rename to "franchiseseasons";
commit;

117
sql/load.sql Normal file
View File

@ -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;

View File

@ -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;

5
sql/seasons.sql Normal file
View File

@ -0,0 +1,5 @@
begin;
create table if not exists "seasons" (
"year" text
);
commit;