lahmanlite/sql/appearances.sql

117 lines
3.3 KiB
PL/PgSQL

pragma foreign_keys = 0;
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table appearances as
select * from "raw".appearances;
alter table appearances drop column "lgID";
update appearances
set teamid = 'WS9'
where teamid = 'WAS' and yearid between 1891 and 1899;
update appearances
set teamid = 'PHP'
where teamid = 'PH4' and yearid between 1890 and 1891;
-- got this missing data from bbref
insert into appearances values
(1896,'BRO','dailyco01',1,null,1,null,0,1,0,0,0,0,0,0,0,0,0,null,null),
(1875,'WS6','thompfr01',11,null,11,null,0,11,0,0,0,0,0,0,1,1,0,null,null);
update appearances
set G_all = 17
where yearid = 2023 and teamid = 'ANA' and playerid = 'adelljo01';
update appearances
set G_all = 159
where yearid = 2023 and teamid = 'ATL' and playerid = 'acunaro01';
update appearances
set G_all = 35
where yearid = 2023 and teamid = 'CIN' and playerid = 'marteno01';
update appearances
set G_all = 136
where yearid = 2023 and teamid = 'DET' and playerid = 'baezja01';
update appearances
set G_all = 90
where yearid = 2023 and teamid = 'HOU' and playerid = 'altuvjo01';
update appearances
set G_all = 80
where yearid = 2023 and teamid = 'MIN' and playerid = 'polanjo01';
update appearances
set G_all = 154
where yearid = 2023 and teamid = 'NYN' and playerid = 'alonspe01';
update appearances
set G_all = 79
where yearid = 2023 and teamid = 'NYN' and playerid = 'phamth01';
update appearances
set G_all = 137
where yearid = 2023 and teamid = 'TBA' and playerid = 'diazya01';
update appearances
set G_all = 99
where yearid = 2023 and teamid = 'WAS' and playerid = 'candeje01';
update appearances
set GS = 135
where yearid = 2023 and teamid = 'ANA' and playerid = 'ohtansh01';
update appearances
set
"G_all" = nullif("G_all",''),
"GS" = nullif("GS",''),
"G_batting" = nullif("G_batting",''),
"G_defense" = nullif("G_defense",''),
"G_p" = nullif("G_p",''),
"G_c" = nullif("G_c",''),
"G_1b" = nullif("G_1b",''),
"G_2b" = nullif("G_2b",''),
"G_3b" = nullif("G_3b",''),
"G_ss" = nullif("G_ss",''),
"G_lf" = nullif("G_lf",''),
"G_cf" = nullif("G_cf",''),
"G_rf" = nullif("G_rf",''),
"G_of" = nullif("G_of",''),
"G_dh" = nullif("G_dh",''),
"G_ph" = nullif("G_ph",''),
"G_pr" = nullif("G_pr",'');
CREATE TABLE IF NOT EXISTS "appearances" (
"year" NUMERIC,
"team" TEXT,
"player" TEXT,
"G_all" NUMERIC,
"GS" NUMERIC check ("GS" <= "G_all"),
"G_batting" NUMERIC check ("G_batting" <= "G_all"),
"G_defense" NUMERIC check ("G_defense" <= "G_all"),
"G_p" NUMERIC check ("G_p" <= "G_all"),
"G_c" NUMERIC check ("G_c" <= "G_all"),
"G_1b" NUMERIC check ("G_1b" <= "G_all"),
"G_2b" NUMERIC check ("G_2b" <= "G_all"),
"G_3b" NUMERIC check ("G_3b" <= "G_all"),
"G_ss" NUMERIC check ("G_ss" <= "G_all"),
"G_lf" NUMERIC check ("G_lf" <= "G_all"),
"G_cf" NUMERIC check ("G_cf" <= "G_all"),
"G_rf" NUMERIC check ("G_rf" <= "G_all"),
-- there should be a G_of <= G_all constraint, but there's a lot of rows that fail and i don't feel like correcting them right now
"G_of" NUMERIC,
"G_dh" NUMERIC check ("G_dh" <= "G_all"),
"G_ph" NUMERIC check ("G_ph" <= "G_all"),
"G_pr" NUMERIC check ("G_pr" <= "G_all"),
PRIMARY KEY("year","team","player"),
foreign key("player") references "people"("ID"),
foreign key("year","team") references "teamseasons"("year","team")
);
insert into main.appearances select distinct * from temp.appearances;
commit;