-
Notifications
You must be signed in to change notification settings - Fork 2
/
Copy pathinsert_assembly_members.sql
200 lines (194 loc) · 5.39 KB
/
insert_assembly_members.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
-- Insert assembly member records for winning race candidates
INSERT INTO assembly_member (
assembly_id
, person_id
, chamber_id
, district
, party_id
, counties
, race_candidate_id
, created_date
)
SELECT
election.assembly_id
, race_candidate.person_id
, CASE
WHEN race_type.name = 'State Senator' THEN 'S'
WHEN race_type.name = 'State Representative' THEN 'H'
END as chamber_id
, race.district
, NULL as party_id
, NULL as counties
, race_candidate.id
, now() as created_date
FROM race_candidate
JOIN race
ON race_id = race.id
JOIN race_type
ON race_type_id = race_type.id
JOIN election
ON election_id = election.id
WHERE rank = 1
-- this excludes primary races
AND election.assembly_id IS NOT NULL
-- and narrows to state legislative races
AND race_type.name IN ('State Senator', 'State Representative')
ORDER BY assembly_id, district;
-- since senators serve four years, insert records for their second assembly
INSERT INTO assembly_member (
assembly_id
, person_id
, chamber_id
, district
, party_id
, counties
, race_candidate_id
, created_date
)
SELECT
assembly_member.assembly_id + 1 as assembly_id
, assembly_member.person_id
, assembly_member.chamber_id
, assembly_member.district
, NULL as party_id
, NULL as counties
, assembly_member.race_candidate_id
, now() as created_date
FROM assembly_member
JOIN race_candidate
ON race_candidate.id = race_candidate_id
JOIN race
ON race.id = race_id
JOIN election
ON election.id = election_id
JOIN election_type
ON election_type_id = election_type.id
WHERE chamber_id = 'S'
-- excluding special elections, these need to be handled separately
AND election.election_type_id <> 'S'
-- exclude the most recent assembly so that we aren't projecting into the future
AND assembly_member.assembly_id < (SELECT max(id) FROM assembly);
-- Jack Goodman was elected to Senate District 29 in Nov. 2005, making sure he is added to the 94th Assembly
INSERT INTO assembly_member (
assembly_id
, person_id
, chamber_id
, district
, party_id
, counties
, race_candidate_id
, created_date
)
SELECT
94 as assembly_id
, assembly_member.person_id
, 'S' as chamber_id
, 29 as district
, NULL as party_id
, NULL as counties
, assembly_member.race_candidate_id
, now() as created_date
FROM assembly_member
JOIN race_candidate
ON assembly_member.person_id = race_candidate.person_id
JOIN race
ON race.id = race_id
JOIN election
ON election.id = election_id
WHERE assembly_member.assembly_id = 93
AND assembly_member.district = 29
AND chamber_id = 'S'
AND election_type_id = 'S';
-- Maida Coleman was elected to the Senate District 5 in Feb. 2002, making sure she is added to the 92nd Assembly
INSERT INTO assembly_member (
assembly_id
, person_id
, chamber_id
, district
, party_id
, counties
, race_candidate_id
, created_date
)
SELECT
92 as assembly_id
, assembly_member.person_id
, 'S' as chamber_id
, 5 as district
, NULL as party_id
, NULL as counties
, assembly_member.race_candidate_id
, now() as created_date
FROM assembly_member
JOIN race_candidate
ON assembly_member.person_id = race_candidate.person_id
JOIN race
ON race.id = race_id
JOIN election
ON election.id = election_id
WHERE assembly_member.assembly_id = 91
AND assembly_member.district = 5
AND chamber_id = 'S'
AND election_date = '2002-02-05';
-- Harry Kennedy was elected to Senate District 3 in Dec 2001, making sure he is in the 92 Assembly
INSERT INTO assembly_member (
assembly_id
, person_id
, chamber_id
, district
, party_id
, counties
, race_candidate_id
, created_date
)
SELECT
92 as assembly_id
, assembly_member.person_id
, 'S' as chamber_id
, 3 as district
, NULL as party
, NULL as counties
, assembly_member.race_candidate_id
, now() as created_date
FROM assembly_member
JOIN race_candidate
ON assembly_member.person_id = race_candidate.person_id
JOIN race
ON race.id = race_id
JOIN election
ON election.id = election_id
WHERE assembly_member.assembly_id = 91
AND assembly_member.district = 3
AND chamber_id = 'S'
AND election_type_id = 'S';
-- Mary Bland was elected to the Senate District 9 in Dec 1998, making sure she is added to the 90th General Assembly
INSERT INTO assembly_member (
assembly_id
, person_id
, chamber_id
, district
, party_id
, counties
, race_candidate_id
, created_date
)
SELECT
90 as assembly_id
, assembly_member.person_id
, 'S' as chamber_id
, 9 as district
, NULL as party
, NULL as counties
, race_candidate_id
, now() as created_date
FROM assembly_member
JOIN race_candidate
ON assembly_member.person_id = race_candidate.person_id
JOIN race
ON race.id = race_id
JOIN election
ON election.id = election_id
WHERE assembly_member.assembly_id = 89
AND assembly_member.district = 9
AND chamber_id = 'S'
AND election_type_id = 'S';