move allstar tables
This commit is contained in:
@@ -1,37 +0,0 @@
|
||||
begin;
|
||||
create table if not exists allstargames (
|
||||
"yearID" numeric,
|
||||
"gameNum" numeric,
|
||||
"gameID" text,
|
||||
primary key("yearID","gameNum")
|
||||
);
|
||||
|
||||
insert into allstargames
|
||||
select distinct yearid, gamenum, gameid
|
||||
from allstarfull;
|
||||
|
||||
alter table allstarfull drop column "gameID";
|
||||
|
||||
alter table allstarfull rename to "allstarstartingpos";
|
||||
|
||||
create table if not exists "allstars" (
|
||||
"playerID" text,
|
||||
"yearID" text,
|
||||
"gameNum" text,
|
||||
"teamID" text,
|
||||
"GP" numeric,
|
||||
primary key("playerID","yearID","gameNum"),
|
||||
foreign key("playerID") references "people"("playerID")
|
||||
);
|
||||
|
||||
insert into allstars
|
||||
select distinct playerid, yearid, gamenum, teamid, gp
|
||||
from allstarstartingpos;
|
||||
|
||||
alter table allstarstartingpos drop column "teamid";
|
||||
alter table allstarstartingpos drop column "lgID";
|
||||
alter table allstarstartingpos drop column "gp";
|
||||
|
||||
delete from allstarstartingpos
|
||||
where startingpos is null;
|
||||
commit;
|
||||
26
sql/allstargames.sql
Normal file
26
sql/allstargames.sql
Normal file
@@ -0,0 +1,26 @@
|
||||
begin;
|
||||
attach database 'baseball-raw.db' as 'raw';
|
||||
create table if not exists allstargames (
|
||||
"year" numeric,
|
||||
"gameNum" numeric,
|
||||
"game" text
|
||||
);
|
||||
|
||||
insert into allstargames
|
||||
select distinct yearid, gamenum, gameid
|
||||
from "raw".allstarfull;
|
||||
|
||||
-- fix game numbers for 1962 all-star games
|
||||
update allstargames
|
||||
set gamenum = 1
|
||||
where game = 'ALS196207100';
|
||||
|
||||
update allstargames
|
||||
set gamenum = 2
|
||||
where game = 'NLS196207300';
|
||||
|
||||
-- 1945 all-star game wasn't played so some rows have no game id
|
||||
update allstargames
|
||||
set game = null
|
||||
where game = '';
|
||||
commit;
|
||||
26
sql/allstars.sql
Normal file
26
sql/allstars.sql
Normal file
@@ -0,0 +1,26 @@
|
||||
begin;
|
||||
attach database 'baseball-raw.db' as 'raw';
|
||||
create table if not exists "allstars" (
|
||||
"player" text,
|
||||
"year" text,
|
||||
"gameNum" text,
|
||||
"team" text,
|
||||
"GP" numeric,
|
||||
"gameID" text
|
||||
);
|
||||
|
||||
insert into allstars
|
||||
select distinct playerid, yearid, gamenum, teamid, gp, gameid
|
||||
from "raw".allstarfull;
|
||||
|
||||
-- fix game numbers for 1962 all-star games
|
||||
update allstars
|
||||
set gamenum = 1
|
||||
where gameid = 'ALS196207100';
|
||||
|
||||
update allstars
|
||||
set gamenum = 2
|
||||
where gameid = 'NLS196207300';
|
||||
|
||||
alter table allstars drop column "gameid";
|
||||
end;
|
||||
24
sql/allstarstartingpos.sql
Normal file
24
sql/allstarstartingpos.sql
Normal file
@@ -0,0 +1,24 @@
|
||||
begin;
|
||||
alter table allstarfull rename to "allstarstartingpos";
|
||||
|
||||
-- fix game numbers for 1962 all-star games
|
||||
update allstarstartingpos
|
||||
set gamenum = 1
|
||||
where gameid = 'ALS196207100';
|
||||
|
||||
update allstarstartingpos
|
||||
set gamenum = 2
|
||||
where gameid = 'NLS196207300';
|
||||
|
||||
alter table allstarstartingpos drop column "gameID";
|
||||
alter table allstarstartingpos drop column "teamid";
|
||||
alter table allstarstartingpos drop column "lgID";
|
||||
alter table allstarstartingpos drop column "gp";
|
||||
|
||||
update allstarstartingpos
|
||||
set startingpos = null
|
||||
where startingpos = '';
|
||||
|
||||
delete from allstarstartingpos
|
||||
where startingpos is null;
|
||||
commit;
|
||||
@@ -1,23 +0,0 @@
|
||||
begin;
|
||||
-- fix game numbers for 1962 all-star games
|
||||
update allstarfull
|
||||
set gamenum = 1
|
||||
where gameid = 'ALS196207100';
|
||||
|
||||
update allstarfull
|
||||
set gamenum = 2
|
||||
where gameid = 'NLS196207300';
|
||||
|
||||
-- david freese has two all-star entries for 2012, one in AL
|
||||
delete from allstarfull
|
||||
where playerid = 'freesda01' and yearid = 2012 and lgid = 'AL';
|
||||
|
||||
-- 1945 all-star game wasn't played so some rows have no game id
|
||||
update allstarfull
|
||||
set gameid = null
|
||||
where gameid = '';
|
||||
|
||||
update allstarfull
|
||||
set startingpos = null
|
||||
where startingpos = '';
|
||||
commit;
|
||||
@@ -1,18 +0,0 @@
|
||||
BEGIN;
|
||||
CREATE TABLE "pk_allstarfull" (
|
||||
"playerID" NUMERIC,
|
||||
"yearID" NUMERIC,
|
||||
"gameNum" NUMERIC,
|
||||
"gameID" NUMERIC,
|
||||
"teamID" NUMERIC,
|
||||
"lgID" NUMERIC,
|
||||
"GP" NUMERIC,
|
||||
"startingPos" NUMERIC,
|
||||
primary key("playerID","yearID","gameNum","startingPos"),
|
||||
foreign key("playerID") references "people"("playerID")
|
||||
);
|
||||
|
||||
INSERT INTO "pk_allstarfull" SELECT DISTINCT * FROM "allstarfull";
|
||||
DROP TABLE "allstarfull";
|
||||
ALTER TABLE "pk_allstarfull" RENAME TO "allstarfull";
|
||||
COMMIT;
|
||||
34
sql/load.sql
34
sql/load.sql
@@ -609,4 +609,38 @@ CREATE TABLE IF NOT EXISTS "managershalf" (
|
||||
);
|
||||
|
||||
insert into managershalf select distinct * from "transformed".managershalf;
|
||||
|
||||
CREATE TABLE "allstarstartingpos" (
|
||||
"player" NUMERIC,
|
||||
"year" NUMERIC,
|
||||
"gameNum" NUMERIC,
|
||||
"startingPos" NUMERIC,
|
||||
primary key("player","year","gameNum","startingPos"),
|
||||
foreign key("player","year","gameNum") references "allstars"("player","year","gameNum")
|
||||
);
|
||||
|
||||
insert into allstarstartingpos select distinct * from "transformed".allstarstartingpos;
|
||||
|
||||
create table if not exists allstargames (
|
||||
"year" numeric,
|
||||
"gameNum" numeric,
|
||||
"game" text,
|
||||
primary key("year","gameNum"),
|
||||
foreign key("year") references "seasons"("year")
|
||||
);
|
||||
|
||||
insert into allstargames select distinct * from "transformed".allstargames;
|
||||
|
||||
create table if not exists "allstars" (
|
||||
"player" text,
|
||||
"year" text,
|
||||
"gameNum" text,
|
||||
"team" text,
|
||||
"GP" numeric,
|
||||
primary key("player","year","gameNum"),
|
||||
foreign key("year","gameNum") references "allstargames"("year","gameNum"),
|
||||
foreign key("player","year","team") references "appearances"("player","year","team")
|
||||
);
|
||||
|
||||
insert into allstars select distinct * from "transformed".allstars;
|
||||
COMMIT;
|
||||
|
||||
Reference in New Issue
Block a user