/* 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 . */ pragma foreign_keys = 0; begin; attach database 'lahman-raw.db' as 'raw'; CREATE TEMP TABLE "allstarstartingpos" ( "player" NUMERIC, "year" NUMERIC, "gameNum" NUMERIC, "league" NUMERIC, "startingPos" NUMERIC, "gameid" text ); insert into "allstarstartingpos" select distinct playerid, yearid, gamenum, lgid, startingpos, gameid from "raw".allstarfull; -- fix game numbers for 1962 all-star games update allstarstartingpos set gamenum = 1 where gameid = 'ALS196207100'; update allstarstartingpos set gamenum = 2 where gameid = 'NLS196207300'; -- rocky colavito was a reserve, not starter delete from allstarstartingpos where gameid = 'ALS196207100' and player = 'colavro01'; alter table allstarstartingpos drop column "gameid"; update allstarstartingpos set startingpos = null where startingpos = ''; delete from allstarstartingpos where startingpos is null; CREATE TABLE "allstarstartingpos" ( "player" NUMERIC, "year" NUMERIC, "gameNum" NUMERIC, "league" NUMERIC, "startingPos" NUMERIC check ("startingPos" in (1,2,3,4,5,6,7,8,9,10)), primary key("year","gameNum","league","startingPos"), foreign key("player","year","gameNum") references "allstars"("player","year","gameNum"), foreign key("league") references "leagues"("ID") ); insert into main.allstarstartingpos select distinct * from temp.allstarstartingpos; commit;