add check constraints
This commit is contained in:
parent
b67dec0630
commit
48dabfd691
|
@ -13,6 +13,18 @@ alter table batting drop column "teamID";
|
|||
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,
|
||||
|
@ -20,20 +32,20 @@ CREATE TABLE IF NOT EXISTS main."batting" (
|
|||
"G" NUMERIC,
|
||||
"AB" NUMERIC,
|
||||
"R" NUMERIC,
|
||||
"H" NUMERIC,
|
||||
"2B" NUMERIC,
|
||||
"3B" NUMERIC,
|
||||
"HR" 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,
|
||||
"IBB" NUMERIC,
|
||||
"SO" NUMERIC check (SO <= AB),
|
||||
"IBB" NUMERIC check (IBB <= BB),
|
||||
"HBP" NUMERIC,
|
||||
"SH" NUMERIC,
|
||||
"SF" NUMERIC,
|
||||
"GIDP" NUMERIC,
|
||||
"GIDP" NUMERIC check (GIDP <= AB),
|
||||
PRIMARY KEY("player","year","stint"),
|
||||
foreign key("year","player","stint") references "playerstints"("year","player","stint")
|
||||
);
|
||||
|
|
|
@ -9,6 +9,18 @@ select * from "raw".battingpost;
|
|||
alter table battingpost drop column "lgID";
|
||||
alter table battingpost drop column "teamID";
|
||||
|
||||
update battingpost
|
||||
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."battingpost" (
|
||||
"year" NUMERIC,
|
||||
"round" NUMERIC,
|
||||
|
@ -16,20 +28,20 @@ CREATE TABLE IF NOT EXISTS main."battingpost" (
|
|||
"G" NUMERIC,
|
||||
"AB" NUMERIC,
|
||||
"R" NUMERIC,
|
||||
"H" NUMERIC,
|
||||
"2B" NUMERIC,
|
||||
"3B" NUMERIC,
|
||||
"HR" 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,
|
||||
"IBB" NUMERIC,
|
||||
"SO" NUMERIC check (SO <= AB),
|
||||
"IBB" NUMERIC check (IBB <= BB),
|
||||
"HBP" NUMERIC,
|
||||
"SH" NUMERIC,
|
||||
"SF" NUMERIC,
|
||||
"GIDP" NUMERIC,
|
||||
"GIDP" NUMERIC check (GIDP <= AB),
|
||||
PRIMARY KEY("year","player","round"),
|
||||
foreign key("player","year") references "appearancespost"("player","year"),
|
||||
foreign key("year","round") references "seriespost"("year","round")
|
||||
|
|
|
@ -14,21 +14,64 @@ update teamseasons
|
|||
set teamid = 'PHP'
|
||||
where teamid = 'PH4' and franchid = 'PHQ';
|
||||
|
||||
-- set game totals from bbref
|
||||
update teamseasons
|
||||
set divwin = null
|
||||
where divwin = '';
|
||||
set G = 160
|
||||
where yearid = 1979 and teamid = 'CHA';
|
||||
|
||||
update teamseasons
|
||||
set wcwin = null
|
||||
where wcwin = '';
|
||||
set G = 161
|
||||
where yearid = 1979 and teamid = 'DET';
|
||||
|
||||
update teamseasons
|
||||
set lgwin = null
|
||||
where lgwin = '';
|
||||
set G = 132
|
||||
where yearid = 1897 and teamid = 'CL4';
|
||||
|
||||
update teamseasons
|
||||
set wswin = null
|
||||
where wswin = '';
|
||||
set G = 155
|
||||
where yearid = 1892 and teamid = 'PIT';
|
||||
|
||||
update teamseasons
|
||||
set G = 18
|
||||
where yearid = 1884 and teamid = 'WIL';
|
||||
|
||||
update teamseasons
|
||||
set G = 105
|
||||
where yearid = 1884 and teamid = 'CNU';
|
||||
|
||||
update teamseasons
|
||||
set G = 80
|
||||
where yearid = 1882 and teamid = 'SL4';
|
||||
|
||||
update teamseasons
|
||||
set G = 80
|
||||
where yearid = 1882 and teamid = 'LS2';
|
||||
|
||||
update teamseasons
|
||||
set
|
||||
G = nullif(G, ''),
|
||||
Ghome = nullif(Ghome, ''),
|
||||
W = nullif(W, ''),
|
||||
L = nullif(L, ''),
|
||||
divwin = nullif(divwin,''),
|
||||
wcwin = nullif(wcwin,''),
|
||||
lgwin = nullif(lgwin,''),
|
||||
wswin = nullif(wswin,''),
|
||||
CG = nullif(CG, ''),
|
||||
SHO = nullif(SHO, ''),
|
||||
SV = nullif(SV, ''),
|
||||
IPouts = nullif(IPouts, ''),
|
||||
H = nullif(H, ''),
|
||||
"2B" = nullif("2B", ''),
|
||||
"3B" = nullif("3B", ''),
|
||||
HR = nullif(HR, ''),
|
||||
ER = nullif(ER, ''),
|
||||
HR = nullif(HR, ''),
|
||||
BB = nullif(BB, ''),
|
||||
SO = nullif(SO, ''),
|
||||
HBP = nullif(HBP, ''),
|
||||
R = nullif(R, ''),
|
||||
SF = nullif(SF, '');
|
||||
|
||||
alter table "teamseasons" drop column "franchID";
|
||||
|
||||
|
@ -38,39 +81,39 @@ create table if not exists main."teamseasons" (
|
|||
"team" TEXT,
|
||||
"division" TEXT,
|
||||
"Rank" NUMERIC,
|
||||
"G" NUMERIC,
|
||||
"Ghome" NUMERIC,
|
||||
"W" NUMERIC,
|
||||
"L" NUMERIC,
|
||||
"DivWin" NUMERIC,
|
||||
"WCWin" NUMERIC,
|
||||
"LgWin" NUMERIC,
|
||||
"WSWin" NUMERIC,
|
||||
"G" NUMERIC check (W + L <= G),
|
||||
"Ghome" NUMERIC check (GHome <= G),
|
||||
"W" NUMERIC check (W <= G),
|
||||
"L" NUMERIC check (L <= G),
|
||||
"DivWin" NUMERIC check (divwin in ('Y','N')),
|
||||
"WCWin" NUMERIC check (wcwin in ('Y','N')),
|
||||
"LgWin" NUMERIC check (lgwin in ('Y','N')),
|
||||
"WSWin" NUMERIC check (wswin in ('Y','N')),
|
||||
"R" NUMERIC,
|
||||
"AB" NUMERIC,
|
||||
"H" NUMERIC,
|
||||
"2B" NUMERIC,
|
||||
"3B" NUMERIC,
|
||||
"HR" NUMERIC,
|
||||
"H" NUMERIC check (H <= AB),
|
||||
"2B" NUMERIC check ("2B" <= H),
|
||||
"3B" NUMERIC check ("3B" <= H),
|
||||
"HR" NUMERIC check (HR <= H),
|
||||
"BB" NUMERIC,
|
||||
"SO" NUMERIC,
|
||||
"SO" NUMERIC check (SO <= AB),
|
||||
"SB" NUMERIC,
|
||||
"CS" NUMERIC,
|
||||
"HBP" NUMERIC,
|
||||
"SF" NUMERIC,
|
||||
"RA" NUMERIC,
|
||||
"ER" NUMERIC,
|
||||
"ER" NUMERIC check (ER <= RA),
|
||||
"ERA" NUMERIC,
|
||||
"CG" NUMERIC,
|
||||
"SHO" NUMERIC,
|
||||
"SV" NUMERIC,
|
||||
"CG" NUMERIC check (CG <= G),
|
||||
"SHO" NUMERIC check (SHO <= G),
|
||||
"SV" NUMERIC check (SV <= G),
|
||||
"IPouts" NUMERIC,
|
||||
"HA" NUMERIC,
|
||||
"HRA" NUMERIC,
|
||||
"HRA" NUMERIC check (HRA <= HA),
|
||||
"BBA" NUMERIC,
|
||||
"SOA" NUMERIC,
|
||||
"SOA" NUMERIC check (SOA <= IPouts),
|
||||
"E" NUMERIC,
|
||||
"DP" NUMERIC,
|
||||
"DP" NUMERIC check (2 * DP <= IPouts),
|
||||
"FP" NUMERIC,
|
||||
"name" NUMERIC,
|
||||
"park" NUMERIC,
|
||||
|
|
Loading…
Reference in New Issue