Skip to content

Commit b53bcd4

Browse files
author
Jan Lindström
committed
MDEV-7367: Updating a virtual column corrupts table which crashes server
Analysis: MySQL table definition contains also virtual columns. Similarly, index fielnr references MySQL table fields. However, InnoDB table definition does not contain virtual columns. Therefore, when matching MySQL key fieldnr we need to use actual column name to find out referenced InnoDB dictionary column name. Fix: Add new function to match MySQL index key columns to InnoDB dictionary.
1 parent 0563f49 commit b53bcd4

File tree

14 files changed

+753
-14
lines changed

14 files changed

+753
-14
lines changed
Lines changed: 322 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,322 @@
1+
CREATE TABLE IF NOT EXISTS gso_grad_supr (
2+
term char(4) NOT NULL DEFAULT '',
3+
uw_id int(8) UNSIGNED NOT NULL DEFAULT 0,
4+
plan varchar(10) NOT NULL DEFAULT '',
5+
wdraw_rsn varchar(4) NOT NULL DEFAULT '',
6+
admit_term char(4) NOT NULL DEFAULT '',
7+
CONSTRAINT gso_grad_supr_pky PRIMARY KEY (uw_id, term)
8+
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
9+
INSERT INTO `gso_grad_supr` VALUES ('1031',2,'CSM','','1009');
10+
INSERT INTO `gso_grad_supr` VALUES ('1035',2,'CSM','ACAD','1009');
11+
CREATE TABLE IF NOT EXISTS grad_degree (
12+
student_id int(8) UNSIGNED NOT NULL,
13+
plan varchar(10) NOT NULL,
14+
admit_term char(4) NOT NULL,
15+
wdraw_rsn varchar(4) NOT NULL DEFAULT '',
16+
ofis_deg_status varchar(15) AS (
17+
CASE
18+
WHEN wdraw_rsn = '' THEN 'In progress'
19+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed'
20+
ELSE 'Not Completed'
21+
END) VIRTUAL,
22+
deg_start_term char(4) NOT NULL DEFAULT '' COMMENT 'Educated guess at the beginning of the data',
23+
deg_as_of_term char(4) NOT NULL COMMENT 'In most cases also end term',
24+
CONSTRAINT grad_degree_stu_plan_admit_pky PRIMARY KEY (student_id, plan, admit_term)
25+
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
26+
CREATE INDEX grad_degree_wdraw_rsn_ndx ON grad_degree (wdraw_rsn);
27+
CREATE INDEX grad_degree_as_of_term_ndx ON grad_degree (deg_as_of_term);
28+
INSERT IGNORE grad_degree (
29+
student_id,
30+
plan,
31+
admit_term,
32+
wdraw_rsn,
33+
deg_start_term,
34+
deg_as_of_term
35+
)
36+
SELECT
37+
ggs.uw_id AS c_student_id,
38+
ggs.plan,
39+
ggs.admit_term,
40+
ggs.wdraw_rsn,
41+
IF( (SELECT COUNT(*) FROM grad_degree AS gd WHERE gd.student_id = ggs.uw_id AND gd.admit_term = ggs.admit_term) > 0, ggs.term, ggs.admit_term ) AS c_deg_start_term,
42+
ggs.term AS c_as_of_term
43+
FROM gso_grad_supr AS ggs
44+
LEFT OUTER JOIN
45+
grad_degree AS gd
46+
ON ( gd.student_id = ggs.uw_id AND gd.plan = ggs.plan AND gd.admit_term = ggs.admit_term )
47+
WHERE
48+
ggs.term = 1031 AND
49+
gd.student_id IS NULL
50+
;
51+
UPDATE grad_degree AS gd
52+
INNER JOIN
53+
gso_grad_supr AS ggs
54+
ON ( gd.student_id = ggs.uw_id AND gd.plan = ggs.plan AND gd.admit_term = ggs.admit_term )
55+
SET
56+
gd.wdraw_rsn = ggs.wdraw_rsn,
57+
gd.deg_as_of_term = 1035
58+
WHERE
59+
gd.wdraw_rsn NOT IN ('DCMP', 'TRDC') AND
60+
ggs.term = 1035
61+
;
62+
drop table grad_degree;
63+
CREATE TABLE IF NOT EXISTS grad_degree (
64+
student_id int(8) UNSIGNED NOT NULL,
65+
plan varchar(10) NOT NULL,
66+
admit_term char(4) NOT NULL,
67+
wdraw_rsn varchar(4) NOT NULL DEFAULT '',
68+
ofis_deg_status varchar(15) AS (
69+
CASE
70+
WHEN wdraw_rsn = '' THEN 'In progress'
71+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed'
72+
ELSE 'Not Completed'
73+
END) VIRTUAL,
74+
ofis_deg_status2 varchar(15) AS (
75+
CASE
76+
WHEN wdraw_rsn = '' THEN 'In progress2'
77+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed2'
78+
ELSE 'Not Completed2'
79+
END) VIRTUAL,
80+
ofis_deg_status3 varchar(15) AS (
81+
CASE
82+
WHEN wdraw_rsn = '' THEN 'In progress3'
83+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed3'
84+
ELSE 'Not Completed3'
85+
END) VIRTUAL,
86+
ofis_deg_status4 varchar(15) AS (
87+
CASE
88+
WHEN wdraw_rsn = '' THEN 'In progress4'
89+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed4'
90+
ELSE 'Not Completed4'
91+
END) VIRTUAL,
92+
ofis_deg_status5 varchar(15) AS (
93+
CASE
94+
WHEN wdraw_rsn = '' THEN 'In progress5'
95+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed5'
96+
ELSE 'Not Completed5'
97+
END) VIRTUAL,
98+
ofis_deg_status6 varchar(15) AS (
99+
CASE
100+
WHEN wdraw_rsn = '' THEN 'In progress6'
101+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed6'
102+
ELSE 'Not Completed6'
103+
END) VIRTUAL,
104+
ofis_deg_status7 varchar(15) AS (
105+
CASE
106+
WHEN wdraw_rsn = '' THEN 'In progress7'
107+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed7'
108+
ELSE 'Not Completed7'
109+
END) VIRTUAL,
110+
ofis_deg_status8 varchar(15) AS (
111+
CASE
112+
WHEN wdraw_rsn = '' THEN 'In progress8'
113+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed8'
114+
ELSE 'Not Completed8'
115+
END) VIRTUAL,
116+
deg_start_term char(4) NOT NULL DEFAULT '' COMMENT 'Educated guess at the beginning of the data',
117+
deg_as_of_term char(4) NOT NULL COMMENT 'In most cases also end term',
118+
CONSTRAINT grad_degree_stu_plan_admit_pky PRIMARY KEY (student_id, plan, admit_term)
119+
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
120+
CREATE INDEX grad_degree_wdraw_rsn_ndx ON grad_degree (wdraw_rsn);
121+
CREATE INDEX grad_degree_as_of_term_ndx ON grad_degree (deg_as_of_term);
122+
INSERT IGNORE grad_degree (
123+
student_id,
124+
plan,
125+
admit_term,
126+
wdraw_rsn,
127+
deg_start_term,
128+
deg_as_of_term
129+
)
130+
SELECT
131+
ggs.uw_id AS c_student_id,
132+
ggs.plan,
133+
ggs.admit_term,
134+
ggs.wdraw_rsn,
135+
IF( (SELECT COUNT(*) FROM grad_degree AS gd WHERE gd.student_id = ggs.uw_id AND gd.admit_term = ggs.admit_term) > 0, ggs.term, ggs.admit_term ) AS c_deg_start_term,
136+
ggs.term AS c_as_of_term
137+
FROM gso_grad_supr AS ggs
138+
LEFT OUTER JOIN
139+
grad_degree AS gd
140+
ON ( gd.student_id = ggs.uw_id AND gd.plan = ggs.plan AND gd.admit_term = ggs.admit_term )
141+
WHERE
142+
ggs.term = 1031 AND
143+
gd.student_id IS NULL
144+
;
145+
UPDATE grad_degree AS gd
146+
INNER JOIN
147+
gso_grad_supr AS ggs
148+
ON ( gd.student_id = ggs.uw_id AND gd.plan = ggs.plan AND gd.admit_term = ggs.admit_term )
149+
SET
150+
gd.wdraw_rsn = ggs.wdraw_rsn,
151+
gd.deg_as_of_term = 1035
152+
WHERE
153+
gd.wdraw_rsn NOT IN ('DCMP', 'TRDC') AND
154+
ggs.term = 1035
155+
;
156+
ALTER TABLE grad_degree DROP INDEX grad_degree_wdraw_rsn_ndx;
157+
ALTER TABLE grad_degree DROP COLUMN deg_start_term;
158+
SHOW CREATE TABLE grad_degree;
159+
Table Create Table
160+
grad_degree CREATE TABLE `grad_degree` (
161+
`student_id` int(8) unsigned NOT NULL,
162+
`plan` varchar(10) NOT NULL,
163+
`admit_term` char(4) NOT NULL,
164+
`wdraw_rsn` varchar(4) NOT NULL DEFAULT '',
165+
`ofis_deg_status` varchar(15) AS (
166+
CASE
167+
WHEN wdraw_rsn = '' THEN 'In progress'
168+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed'
169+
ELSE 'Not Completed'
170+
END) VIRTUAL,
171+
`ofis_deg_status2` varchar(15) AS (
172+
CASE
173+
WHEN wdraw_rsn = '' THEN 'In progress2'
174+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed2'
175+
ELSE 'Not Completed2'
176+
END) VIRTUAL,
177+
`ofis_deg_status3` varchar(15) AS (
178+
CASE
179+
WHEN wdraw_rsn = '' THEN 'In progress3'
180+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed3'
181+
ELSE 'Not Completed3'
182+
END) VIRTUAL,
183+
`ofis_deg_status4` varchar(15) AS (
184+
CASE
185+
WHEN wdraw_rsn = '' THEN 'In progress4'
186+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed4'
187+
ELSE 'Not Completed4'
188+
END) VIRTUAL,
189+
`ofis_deg_status5` varchar(15) AS (
190+
CASE
191+
WHEN wdraw_rsn = '' THEN 'In progress5'
192+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed5'
193+
ELSE 'Not Completed5'
194+
END) VIRTUAL,
195+
`ofis_deg_status6` varchar(15) AS (
196+
CASE
197+
WHEN wdraw_rsn = '' THEN 'In progress6'
198+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed6'
199+
ELSE 'Not Completed6'
200+
END) VIRTUAL,
201+
`ofis_deg_status7` varchar(15) AS (
202+
CASE
203+
WHEN wdraw_rsn = '' THEN 'In progress7'
204+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed7'
205+
ELSE 'Not Completed7'
206+
END) VIRTUAL,
207+
`ofis_deg_status8` varchar(15) AS (
208+
CASE
209+
WHEN wdraw_rsn = '' THEN 'In progress8'
210+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed8'
211+
ELSE 'Not Completed8'
212+
END) VIRTUAL,
213+
`deg_as_of_term` char(4) NOT NULL COMMENT 'In most cases also end term',
214+
PRIMARY KEY (`student_id`,`plan`,`admit_term`),
215+
KEY `grad_degree_as_of_term_ndx` (`deg_as_of_term`)
216+
) ENGINE=InnoDB DEFAULT CHARSET=utf8
217+
DROP TABLE grad_degree;
218+
CREATE TABLE IF NOT EXISTS grad_degree (
219+
student_id int(8) UNSIGNED NOT NULL,
220+
plan varchar(10) NOT NULL,
221+
admit_term char(4) NOT NULL,
222+
wdraw_rsn varchar(4) NOT NULL DEFAULT '',
223+
ofis_deg_status varchar(15) AS (
224+
CASE
225+
WHEN wdraw_rsn = '' THEN 'In progress'
226+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed'
227+
ELSE 'Not Completed'
228+
END) VIRTUAL,
229+
ofis_deg_status2 varchar(15) AS (
230+
CASE
231+
WHEN wdraw_rsn = '' THEN 'In progress2'
232+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed2'
233+
ELSE 'Not Completed2'
234+
END) VIRTUAL,
235+
ofis_deg_status3 varchar(15) AS (
236+
CASE
237+
WHEN wdraw_rsn = '' THEN 'In progress3'
238+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed3'
239+
ELSE 'Not Completed3'
240+
END) VIRTUAL,
241+
ofis_deg_status4 varchar(15) AS (
242+
CASE
243+
WHEN wdraw_rsn = '' THEN 'In progress4'
244+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed4'
245+
ELSE 'Not Completed4'
246+
END) VIRTUAL,
247+
ofis_deg_status5 varchar(15) AS (
248+
CASE
249+
WHEN wdraw_rsn = '' THEN 'In progress5'
250+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed5'
251+
ELSE 'Not Completed5'
252+
END) VIRTUAL,
253+
ofis_deg_status6 varchar(15) AS (
254+
CASE
255+
WHEN wdraw_rsn = '' THEN 'In progress6'
256+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed6'
257+
ELSE 'Not Completed6'
258+
END) VIRTUAL,
259+
ofis_deg_status7 varchar(15) AS (
260+
CASE
261+
WHEN wdraw_rsn = '' THEN 'In progress7'
262+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed7'
263+
ELSE 'Not Completed7'
264+
END) VIRTUAL,
265+
ofis_deg_status8 varchar(15) AS (
266+
CASE
267+
WHEN wdraw_rsn = '' THEN 'In progress8'
268+
WHEN wdraw_rsn = 'DCMP' OR wdraw_rsn = 'TRDC' THEN 'Completed8'
269+
ELSE 'Not Completed8'
270+
END) VIRTUAL,
271+
deg_start_term char(4) NOT NULL DEFAULT '' COMMENT 'Educated guess at the beginning of the data',
272+
deg_as_of_term char(4) NOT NULL COMMENT 'In most cases also end term',
273+
CONSTRAINT grad_degree_stu_plan_admit_pky PRIMARY KEY (student_id, plan, admit_term)
274+
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
275+
CREATE INDEX grad_degree_wdraw_rsn_ndx ON grad_degree (wdraw_rsn);
276+
ALTER TABLE grad_degree DROP COLUMN ofis_deg_status2, DROP COLUMN ofis_deg_status3,
277+
DROP COLUMN ofis_deg_status4, DROP COLUMN ofis_deg_status5, DROP COLUMN ofis_deg_status6,
278+
DROP COLUMN ofis_deg_status7, DROP COLUMN ofis_deg_status8;
279+
CREATE INDEX grad_degree_as_of_term_ndx ON grad_degree (deg_as_of_term);
280+
INSERT IGNORE grad_degree (
281+
student_id,
282+
plan,
283+
admit_term,
284+
wdraw_rsn,
285+
deg_start_term,
286+
deg_as_of_term
287+
)
288+
SELECT
289+
ggs.uw_id AS c_student_id,
290+
ggs.plan,
291+
ggs.admit_term,
292+
ggs.wdraw_rsn,
293+
IF( (SELECT COUNT(*) FROM grad_degree AS gd WHERE gd.student_id = ggs.uw_id AND gd.admit_term = ggs.admit_term) > 0, ggs.term, ggs.admit_term ) AS c_deg_start_term,
294+
ggs.term AS c_as_of_term
295+
FROM gso_grad_supr AS ggs
296+
LEFT OUTER JOIN
297+
grad_degree AS gd
298+
ON ( gd.student_id = ggs.uw_id AND gd.plan = ggs.plan AND gd.admit_term = ggs.admit_term )
299+
WHERE
300+
ggs.term = 1031 AND
301+
gd.student_id IS NULL
302+
;
303+
UPDATE grad_degree AS gd
304+
INNER JOIN
305+
gso_grad_supr AS ggs
306+
ON ( gd.student_id = ggs.uw_id AND gd.plan = ggs.plan AND gd.admit_term = ggs.admit_term )
307+
SET
308+
gd.wdraw_rsn = ggs.wdraw_rsn,
309+
gd.deg_as_of_term = 1035
310+
WHERE
311+
gd.wdraw_rsn NOT IN ('DCMP', 'TRDC') AND
312+
ggs.term = 1035
313+
;
314+
select * from grad_degree;
315+
student_id plan admit_term wdraw_rsn ofis_deg_status deg_start_term deg_as_of_term
316+
2 CSM 1009 ACAD Not Completed 1009 1035
317+
select * from gso_grad_supr;
318+
term uw_id plan wdraw_rsn admit_term
319+
1031 2 CSM 1009
320+
1035 2 CSM ACAD 1009
321+
drop table grad_degree;
322+
drop table gso_grad_supr;

0 commit comments

Comments
 (0)