lahmanlite/sql/batting.sql

58 lines
1.3 KiB
PL/PgSQL

pragma foreign_keys = 0;
begin;
attach database 'baseball-raw.db' as 'raw';
create temp table batting as
select * from "raw".batting;
alter table batting drop column "lgID";
alter table batting drop column "teamID";
alter table batting drop column "G";
alter table batting drop column "G_batting";
-- bbref doesn't say this guy played in 1911
delete from batting
where playerid = 'smithbu01' and yearid = 1911;
update batting
set
RBI = nullif(RBI,''),
SB = nullif(SB,''),
CS = nullif(CS,''),
SO = nullif(SO,''),
IBB = nullif(IBB,''),
HBP = nullif(HBP,''),
SH = nullif(SH,''),
SF = nullif(SF,''),
GIDP = nullif(GIDP,'');
CREATE TABLE IF NOT EXISTS main."batting" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"AB" NUMERIC,
"R" NUMERIC,
"H" NUMERIC check (H <= AB),
"2B" NUMERIC check ("2B" <= H),
"3B" NUMERIC check ("3B" <= H),
"HR" NUMERIC check ("HR" <= H),
"RBI" NUMERIC,
"SB" NUMERIC,
"CS" NUMERIC,
"BB" NUMERIC,
"SO" NUMERIC check (SO <= AB),
"IBB" NUMERIC check (IBB <= BB),
"HBP" NUMERIC,
"SH" NUMERIC,
"SF" NUMERIC,
"GIDP" NUMERIC check (GIDP <= AB),
"G_old" NUMERIC check (GIDP <= AB),
PRIMARY KEY("player","year","stint"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);
insert into main.batting select distinct * from temp."batting";
commit;