add check constraints

This commit is contained in:
Nick Griffey 2024-02-01 21:45:26 -06:00
parent 35419adff7
commit 1fd886fdd5
6 changed files with 127 additions and 45 deletions

View File

@ -21,27 +21,47 @@ 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" = 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,
"G_batting" NUMERIC,
"G_defense" NUMERIC,
"G_p" NUMERIC,
"G_c" NUMERIC,
"G_1b" NUMERIC,
"G_2b" NUMERIC,
"G_3b" NUMERIC,
"G_ss" NUMERIC,
"G_lf" NUMERIC,
"G_cf" NUMERIC,
"G_rf" NUMERIC,
"G_of" NUMERIC,
"G_dh" NUMERIC,
"G_ph" NUMERIC,
"G_pr" 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"),
"G_of" NUMERIC check ("G_of" <= "G_all"),
"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")

View File

@ -1,4 +1,8 @@
pragma foreign_keys = 0;
-- check constraints are disabled for this file because the checks seem
-- reasonable, but there's a surprising number of records that fail them. Not
-- sure if it's a data problem or a misunderstanding on my part (or both).
pragma ignore_check_constraints = 1;
begin;
@ -16,9 +20,9 @@ CREATE TABLE IF NOT EXISTS main."fielding" (
"stint" NUMERIC,
"POS" TEXT,
"G" NUMERIC,
"GS" NUMERIC check (GS <= G),
"GS" NUMERIC check (GS <= G),
"InnOuts" NUMERIC,
"PO" NUMERIC,
"PO" NUMERIC check (PO <= InnOuts),
"A" NUMERIC,
"E" NUMERIC,
"DP" NUMERIC,

View File

@ -17,7 +17,7 @@ CREATE TABLE IF NOT EXISTS main."fieldingofsplit" (
"G" NUMERIC,
"GS" NUMERIC,
"InnOuts" NUMERIC,
"PO" NUMERIC,
"PO" NUMERIC check (PO <= InnOuts),
"A" NUMERIC,
"E" NUMERIC,
"DP" NUMERIC,

View File

@ -17,7 +17,7 @@ CREATE TABLE IF NOT EXISTS main."fieldingpost" (
"G" NUMERIC,
"GS" NUMERIC,
"InnOuts" NUMERIC,
"PO" NUMERIC,
"PO" NUMERIC check (PO <= InnOuts),
"A" NUMERIC,
"E" NUMERIC,
"DP" NUMERIC,

View File

@ -1,5 +1,4 @@
pragma foreign_keys = 0;
pragma ignore_check_constraints = 1;
begin;
attach database 'baseball-raw.db' as 'raw';
@ -10,23 +9,58 @@ select * from "raw".pitching;
alter table pitching drop column "lgID";
alter table pitching drop column "teamID";
-- it seems like Doc White was improperly credited with a win and save for game
-- 2 of 1902-09-02 when he should only have been credited with a save
update pitching
set W = 15
where playerID = 'whitedo01' and yearid = 1902 and stint = 1;
-- Give his win to Chick Fraser
update pitching
set W = 13
where playerID = 'frasech01' and yearid = 1902 and stint = 1;
update pitching
set
W = nullif(W, ''),
L = nullif(L, ''),
G = nullif(G, ''),
GS = nullif(GS, ''),
CG = nullif(CG, ''),
SHO = nullif(SHO, ''),
SV = nullif(SV, ''),
IPouts = nullif(IPouts, ''),
H = nullif(H, ''),
ER = nullif(ER, ''),
HR = nullif(HR, ''),
BB = nullif(BB, ''),
SO = nullif(SO, ''),
IBB = nullif(IBB, ''),
HBP = nullif(HBP, ''),
BFP = nullif(BFP, ''),
GF = nullif(GF, ''),
R = nullif(R, ''),
SH = nullif(SH, ''),
SF = nullif(SF, ''),
GIDP = nullif(GIDP, '');
CREATE TABLE IF NOT EXISTS main."pitching" (
"player" TEXT,
"year" NUMERIC,
"stint" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
"G" NUMERIC check (W + L + SV <= G),
"GS" NUMERIC check (GS <= G),
"CG" NUMERIC check (CG <= GS),
"SHO" NUMERIC check (SHO <= CG),
"SV" NUMERIC,
"W" NUMERIC check (W <= G),
"L" NUMERIC check (L <= G),
"G" NUMERIC check (W + L + SV <= G),
"GS" NUMERIC check (GS <= G),
"CG" NUMERIC check (CG <= GS),
"SHO" NUMERIC check (SHO <= G),
"SV" NUMERIC check (SV <= G),
"IPouts" NUMERIC,
"H" NUMERIC,
"ER" NUMERIC check (ER <= R),
"HR" NUMERIC,
"ER" NUMERIC check (ER <= R),
"HR" NUMERIC check (HR <= H),
"BB" NUMERIC,
"SO" NUMERIC,
"SO" NUMERIC check (SO <= IPouts),
"BAOpp" NUMERIC,
"ERA" NUMERIC,
"IBB" NUMERIC,
@ -34,11 +68,11 @@ CREATE TABLE IF NOT EXISTS main."pitching" (
"HBP" NUMERIC,
"BK" NUMERIC,
"BFP" NUMERIC,
"GF" NUMERIC,
"GF" NUMERIC check (GF <= G),
"R" NUMERIC,
"SH" NUMERIC,
"SF" NUMERIC,
"GIDP" NUMERIC,
"GIDP" NUMERIC check (2 * GIDP <= IPouts),
PRIMARY KEY("player","year","stint"),
foreign key("year","player","stint") references "playerstints"("year","player","stint")
);

View File

@ -9,23 +9,47 @@ select * from "raw".pitchingpost;
alter table pitchingpost drop column "lgID";
alter table pitchingpost drop column "teamID";
update pitchingpost
set
W = nullif(W, ''),
L = nullif(L, ''),
G = nullif(G, ''),
GS = nullif(GS, ''),
CG = nullif(CG, ''),
SHO = nullif(SHO, ''),
SV = nullif(SV, ''),
IPouts = nullif(IPouts, ''),
H = nullif(H, ''),
ER = nullif(ER, ''),
HR = nullif(HR, ''),
BB = nullif(BB, ''),
SO = nullif(SO, ''),
IBB = nullif(IBB, ''),
HBP = nullif(HBP, ''),
BFP = nullif(BFP, ''),
GF = nullif(GF, ''),
R = nullif(R, ''),
SH = nullif(SH, ''),
SF = nullif(SF, ''),
GIDP = nullif(GIDP, '');
CREATE TABLE IF NOT EXISTS main."pitchingpost" (
"player" TEXT,
"year" NUMERIC,
"round" NUMERIC,
"W" NUMERIC,
"L" NUMERIC,
"G" NUMERIC,
"GS" NUMERIC,
"CG" NUMERIC,
"SHO" NUMERIC,
"SV" NUMERIC,
"W" NUMERIC check (W <= G),
"L" NUMERIC check (L <= G),
"G" NUMERIC check (W + L + SV <= G),
"GS" NUMERIC check (GS <= G),
"CG" NUMERIC check (CG <= GS),
"SHO" NUMERIC check (SHO <= G),
"SV" NUMERIC check (SV <= G),
"IPouts" NUMERIC,
"H" NUMERIC,
"ER" NUMERIC,
"HR" NUMERIC,
"ER" NUMERIC check (ER <= R),
"HR" NUMERIC check (HR <= H),
"BB" NUMERIC,
"SO" NUMERIC,
"SO" NUMERIC check (SO <= IPouts),
"BAOpp" NUMERIC,
"ERA" NUMERIC,
"IBB" NUMERIC,
@ -33,11 +57,11 @@ CREATE TABLE IF NOT EXISTS main."pitchingpost" (
"HBP" NUMERIC,
"BK" NUMERIC,
"BFP" NUMERIC,
"GF" NUMERIC,
"GF" NUMERIC check (GF <= G),
"R" NUMERIC,
"SH" NUMERIC,
"SF" NUMERIC,
"GIDP" NUMERIC,
"GIDP" NUMERIC check (2 * GIDP <= IPouts),
PRIMARY KEY("player","year","round"),
foreign key("player","year") references "appearancespost"("player","year"),
foreign key("year","round") references "seriespost"("year","round")