80 lines
2.0 KiB
PL/PgSQL
80 lines
2.0 KiB
PL/PgSQL
/*
|
|
Copyright (C) 2024 filifa
|
|
|
|
This program is free software: you can redistribute it and/or modify it under
|
|
the terms of the GNU General Public License as published by the Free Software
|
|
Foundation, either version 3 of the License, or (at your option) any later
|
|
version.
|
|
|
|
This program is distributed in the hope that it will be useful, but WITHOUT ANY
|
|
WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR A
|
|
PARTICULAR PURPOSE. See the GNU General Public License for more details.
|
|
|
|
You should have received a copy of the GNU General Public License along with
|
|
this program. If not, see <https://www.gnu.org/licenses/>.
|
|
*/
|
|
|
|
pragma foreign_keys = 0;
|
|
|
|
begin;
|
|
attach database 'lahman-raw.db' as 'raw';
|
|
create temp table if not exists "allstars" (
|
|
"player" text,
|
|
"year" text,
|
|
"gameNum" text,
|
|
"team" text,
|
|
"GP" numeric,
|
|
"gameID" text
|
|
);
|
|
|
|
insert into allstars
|
|
select distinct playerid, yearid, gamenum, teamid, gp, gameid
|
|
from "raw".allstarfull;
|
|
|
|
-- fix game numbers for 1962 all-star games
|
|
update allstars
|
|
set gamenum = 1
|
|
where gameid = 'ALS196207100';
|
|
|
|
update allstars
|
|
set gamenum = 2
|
|
where gameid = 'NLS196207300';
|
|
|
|
alter table allstars drop column "gameid";
|
|
|
|
-- correct team codes for whole seasons
|
|
update allstars
|
|
set team = 'ANA'
|
|
where year between 1997 and 2004 and team = 'LAA';
|
|
|
|
update allstars
|
|
set team = 'ML4'
|
|
where year between 1970 and 1997 and team = 'MIL';
|
|
|
|
update allstars
|
|
set team = 'ML1'
|
|
where year between 1953 and 1965 and team = 'MLN';
|
|
|
|
-- correct team codes for one-off errors
|
|
update allstars
|
|
set team = 'NYA'
|
|
where player = 'chapmbe01' and year = 1933;
|
|
|
|
update allstars
|
|
set team = 'ATL'
|
|
where player = 'contrwi02' and year = 2022;
|
|
|
|
create table if not exists "allstars" (
|
|
"player" text,
|
|
"year" text,
|
|
"gameNum" text,
|
|
"team" text,
|
|
"GP" numeric check ("GP" in (0, 1)),
|
|
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 main.allstars select distinct * from temp.allstars;
|
|
end;
|