lahmanlite/sql/teamseasons.sql

95 lines
1.7 KiB
PL/PgSQL

pragma foreign_keys = 0;
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table teamseasons as
select * from teams;
update teamseasons
set teamid = 'WS9'
where teamid = 'WAS' and franchid = 'WAS';
update teamseasons
set teamid = 'PHP'
where teamid = 'PH4' and franchid = 'PHQ';
update teamseasons
set divwin = null
where divwin = '';
update teamseasons
set wcwin = null
where wcwin = '';
update teamseasons
set lgwin = null
where lgwin = '';
update teamseasons
set wswin = null
where wswin = '';
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"),
UNIQUE("year","teamIDBR"),
UNIQUE("year","teamIDlahman45"),
UNIQUE("year","teamIDretro"),
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;