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
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
|
--source include/innodb_page_size.inc
--echo #
--echo # MDEV-11369: Instant ADD COLUMN for InnoDB
--echo #
let $format= `SELECT CASE WHEN @@GLOBAL.innodb_page_size>16384
THEN 'DYNAMIC' ELSE 'COMPRESSED' END`;
CREATE TABLE t(a INT UNIQUE)ENGINE=InnoDB ROW_FORMAT=COMPACT;
eval ALTER TABLE t ADD e INT, ROW_FORMAT=$format;
INSERT INTO t SET a=1;
SET @old_instant=
(SELECT variable_value FROM information_schema.global_status
WHERE variable_name = 'innodb_instant_alter_column');
--enable_info
ALTER TABLE t ADD b INT NOT NULL, ALGORITHM=COPY;
ALTER TABLE t ADD c INT NOT NULL, FORCE;
--disable_info
SELECT variable_value-@old_instant instants
FROM information_schema.global_status
WHERE variable_name = 'innodb_instant_alter_column';
--enable_info
ALTER TABLE t ADD d INT NOT NULL;
--disable_info
SELECT * FROM t;
SHOW CREATE TABLE t;
SELECT variable_value-@old_instant instants
FROM information_schema.global_status
WHERE variable_name = 'innodb_instant_alter_column';
SELECT variable_value-@old_instant instants
FROM information_schema.global_status
WHERE variable_name = 'innodb_instant_alter_column';
DROP TABLE t;
connect analyze, localhost, root;
connection default;
SET timestamp = 42;
SET time_zone='+03:00';
SET @saved_frequency= @@GLOBAL.innodb_purge_rseg_truncate_frequency;
SET GLOBAL innodb_purge_rseg_truncate_frequency=1;
SET @old_instant=
(SELECT variable_value FROM information_schema.global_status
WHERE variable_name = 'innodb_instant_alter_column');
let $format= 3;
while ($format) {
let $engine= `SELECT CONCAT('ENGINE=InnoDB ROW_FORMAT=',CASE $format
WHEN 1 THEN 'DYNAMIC'
WHEN 2 THEN 'COMPACT'
ELSE 'REDUNDANT' END)`;
eval CREATE TABLE t1
(id INT PRIMARY KEY, c2 INT UNIQUE,
c3 POINT NOT NULL DEFAULT ST_GeomFromText('POINT(3 4)'),
SPATIAL INDEX(c3)) $engine;
INSERT INTO t1 (id, c2) values(1,1);
SELECT id,c2,ST_AsText(c3) c3 FROM t1;
--enable_info
ALTER TABLE t1 ADD COLUMN (
d1 INT, d2 INT UNSIGNED DEFAULT 10, d3 VARCHAR(20) NOT NULL DEFAULT 'abcde',
d4 TIMESTAMP NOT NULL DEFAULT current_timestamp());
ALTER TABLE t1 ADD INDEX(d3);
--disable_info
BEGIN;
UPDATE t1 SET d3='';
ROLLBACK;
SELECT id,c2,ST_AsText(c3) c3, d1, d2, d3, d4 FROM t1;
INSERT INTO t1 (id) VALUES(2),(3),(4),(5),(6);
--enable_info
ALTER TABLE t1 CHANGE d1 d1 INT DEFAULT 5, CHANGE d2 d2 INT DEFAULT 15,
CHANGE d3 d3 VARCHAR(20) NOT NULL DEFAULT 'fghij',
CHANGE d4 dfour TIMESTAMP NOT NULL DEFAULT now();
--disable_info
UPDATE t1 SET d3='foo' WHERE id = 2;
UPDATE t1 SET d3=DEFAULT WHERE id = 4;
INSERT INTO t1 SET id = 7;
SELECT id,c2,ST_AsText(c3) c3, d1, d2, d3, dfour FROM t1;
CHECK TABLE t1;
# add virtual columns
--enable_info
ALTER TABLE t1 ADD COLUMN e1 INT AS (id * 3);
ALTER TABLE t1 ADD COLUMN e2 VARCHAR(30) AS (d3);
ALTER TABLE t1 ADD COLUMN e3 INT AS (id * 2);
# instant alter
ALTER TABLE t1 CHANGE d3 d3 VARCHAR(20) NOT NULL DEFAULT 'foobar',
ADD COLUMN (d5 CHAR(20) DEFAULT 'hijkl', d6 INT DEFAULT -12345, d7 INT),
DROP INDEX d3;
--disable_info
INSERT INTO t1 SET id = 8;
# Updating a column by extending an existing record
UPDATE t1 SET d3 = 'yyyyy' WHERE id = 1;
# Updating an already materialized column
UPDATE t1 SET d3 = 'xxxxx' WHERE id = 2;
# transaction rollback
BEGIN;
UPDATE t1 SET d3 = 'xxxxx' WHERE id = 3;
SELECT id, c2, ST_AsText(c3) c3, d1, d2, d3, dfour, e1, e2, e3, d5, d6, d7 FROM t1 WHERE id = 3;
ROLLBACK;
SELECT id, c2, ST_AsText(c3) c3, d1, d2, d3, dfour, e1, e2, e3, d5, d6, d7 FROM t1 WHERE id = 3;
# NULL to NULL, no change
BEGIN;
UPDATE t1 SET d7 = NULL WHERE ID = 5;
ROLLBACK;
BEGIN;
UPDATE t1 SET d7 = NULL, d6 = 10 WHERE id = 5;
SELECT id, c2, ST_AsText(c3) c3, d1, d2, d3, dfour, e1, e2, e3, d5, d6, d7 FROM t1 WHERE id = 5;
ROLLBACK;
SELECT id, c2, ST_AsText(c3) c3, d1, d2, d3, dfour, e1, e2, e3, d5, d6, d7 FROM t1 WHERE id = 5;
# add virtual stored columns; not instant
--enable_info
ALTER TABLE t1 ADD COLUMN (f1 VARCHAR(20) AS (concat('x', e2)) STORED);
# instant add
ALTER TABLE t1 ADD COLUMN (d8 VARCHAR(20) DEFAULT 'omnopq');
--disable_info
SELECT id, c2, ST_AsText(c3) c3, d1, d2, d3, dfour, e1, e2, e3, d5, d6, d7, f1, d8 FROM t1;
SHOW CREATE TABLE t1;
--enable_info
ALTER TABLE t1
CHANGE c2 c2 INT DEFAULT 42,
CHANGE d1 d1 INT DEFAULT 1,
CHANGE d2 d2 INT DEFAULT 20,
CHANGE d3 d3 VARCHAR(20) NOT NULL DEFAULT 'boofar';
--disable_info
INSERT INTO t1 SET id=9;
--enable_info
ALTER TABLE t1 DROP c3;
--disable_info
SHOW CREATE TABLE t1;
SELECT * FROM t1;
eval CREATE TABLE t2
(id INT primary key, c1 VARCHAR(4000),
p GEOMETRY NOT NULL DEFAULT ST_GeomFromText('LINESTRING(0 0,0 1,1 1)'),
SPATIAL INDEX(p))
$engine;
BEGIN;
INSERT INTO t2 SET id=1, c1=REPEAT('a', 4000);
INSERT INTO t2 SET id=2, c1=REPEAT('a', 4000), p=ST_GeomFromText('POINT(1 1)');
COMMIT;
--enable_info
ALTER TABLE t2 ADD COLUMN d1 VARCHAR(2000) DEFAULT REPEAT('asdf',500);
--disable_info
SELECT id, c1, ST_AsText(p) p, d1 FROM t2;
# inplace update, rollback
BEGIN;
UPDATE t2 SET c1 = repeat(id, 4000);
connection analyze;
ANALYZE TABLE t2;
SELECT clust_index_size FROM INFORMATION_SCHEMA.INNODB_SYS_TABLESTATS
WHERE name = 'test/t2';
connection default;
ROLLBACK;
connection analyze;
ANALYZE TABLE t2;
SELECT clust_index_size FROM INFORMATION_SCHEMA.INNODB_SYS_TABLESTATS
WHERE name = 'test/t2';
connection default;
# non-inplace update. Rollback MUST NOT materialize off-page columns.
BEGIN;
UPDATE t2 SET d1 = repeat(id, 200);
connection analyze;
ANALYZE TABLE t2;
SELECT clust_index_size FROM INFORMATION_SCHEMA.INNODB_SYS_TABLESTATS
WHERE name = 'test/t2';
connection default;
ROLLBACK;
connection analyze;
ANALYZE TABLE t2;
SELECT clust_index_size FROM INFORMATION_SCHEMA.INNODB_SYS_TABLESTATS
WHERE name = 'test/t2';
connection default;
--enable_info
ALTER TABLE t2 DROP p;
--disable_info
SELECT * FROM t2;
# datetime
eval CREATE TABLE t3
(id INT PRIMARY KEY, c2 INT UNSIGNED NOT NULL UNIQUE,
c3 POLYGON NOT NULL DEFAULT ST_PolyFromText('POLYGON((1 1,2 2,3 3,1 1))'),
SPATIAL INDEX(c3))
$engine;
INSERT INTO t3(id,c2) VALUES(1,1),(2,2),(3,3);
SELECT id, c2, ST_AsText(c3) c3 FROM t3;
--enable_info
ALTER TABLE t3 ADD COLUMN
(c4 DATETIME DEFAULT current_timestamp(),
c5 TIMESTAMP NOT NULL DEFAULT current_timestamp(),
c6 POINT);
SELECT id, c2, ST_AsText(c3) c3, c4, c5, c6 FROM t3;
ALTER TABLE t3 ADD COLUMN c7 TIME NOT NULL DEFAULT current_timestamp();
ALTER TABLE t3 ADD COLUMN c8 DATE NOT NULL DEFAULT current_timestamp();
--disable_info
SELECT id, c2, ST_AsText(c3) c3, c4, c5, c6, c7, c8 FROM t3;
--enable_info
ALTER TABLE t3 ADD COLUMN t TEXT CHARSET utf8
DEFAULT 'The quick brown fox jumps over the lazy dog';
ALTER TABLE t3 ADD COLUMN b BLOB NOT NULL;
--error ER_NO_DEFAULT_FOR_FIELD
INSERT INTO t3 SET id=4;
INSERT INTO t3 SET id=4, c2=0, b=0xf09f98b1;
ALTER TABLE t3 CHANGE t phrase TEXT DEFAULT 0xc3a4c3a448,
CHANGE b b BLOB NOT NULL DEFAULT 'binary line of business';
--disable_info
INSERT INTO t3 SET id=5, c2=9;
SELECT id, c2, ST_AsText(c3) c3, c4, c5, c6, c7, c8, phrase, b FROM t3;
--enable_info
ALTER TABLE t3 DROP c3, DROP c7;
--disable_info
SELECT * FROM t3;
eval CREATE TABLE t4
(id INT, foo INT DEFAULT 0, c1 VARCHAR(4000),
p GEOMETRY NOT NULL DEFAULT ST_GeomFromText('LINESTRING(0 0,0 1,1 1)'),
PRIMARY KEY(id,foo))
$engine;
INSERT INTO t4 (id,c1) VALUES (1, REPEAT('a', 4000)), (2, REPEAT('a', 4000));
ALTER TABLE t4 ADD COLUMN d1 INT;
BEGIN;
UPDATE t4 SET c1 = repeat('1', 4000), foo=1 WHERE id=1;
INSERT INTO t4 (id,c1) VALUES (1, REPEAT('a', 4000));
UPDATE t4 SET c1 = repeat('2', 4000), foo=1 WHERE id=2;
ROLLBACK;
BEGIN;
UPDATE t4 SET d1 = 1,foo=2 WHERE id=1;
INSERT INTO t4 (id,foo,c1) VALUES (1, 1, REPEAT('1', 4000));
COMMIT;
eval CREATE TABLE big
(id INT PRIMARY KEY, c1 VARCHAR(4000), c2 VARCHAR(4000), c3 VARCHAR(1000),
p POINT NOT NULL DEFAULT ST_GeomFromText('POINT(0 0)'), SPATIAL INDEX(p))
$engine;
BEGIN;
INSERT INTO big
SET id=1, c1=REPEAT('a', 200), c2=REPEAT('b', 200), c3=REPEAT('c', 159);
SET @i:=1;
INSERT INTO big SELECT @i:=@i+1, c1, c2, c3, p FROM big;
INSERT INTO big SELECT @i:=@i+1, c1, c2, c3, p FROM big;
INSERT INTO big SELECT @i:=@i+1, c1, c2, c3, p FROM big;
INSERT INTO big SELECT @i:=@i+1, c1, c2, c3, p FROM big;
INSERT INTO big SELECT @i:=@i+1, c1, c2, c3, p FROM big;
COMMIT;
connection analyze;
ANALYZE TABLE big;
SELECT clust_index_size FROM INFORMATION_SCHEMA.INNODB_SYS_TABLESTATS
WHERE name = 'test/big';
connection default;
--enable_info
ALTER TABLE big ADD COLUMN
(d1 INT DEFAULT 0, d2 VARCHAR(20) DEFAULT 'abcde',
d3 TIMESTAMP NOT NULL DEFAULT current_timestamp ON UPDATE current_timestamp);
--disable_info
CHECKSUM TABLE big;
BEGIN;
INSERT INTO big(id, c1, c2, c3) SELECT @i:=@i+1, c1, c2, c3 FROM big;
INSERT INTO big(id, c1, c2, c3) SELECT @i:=@i+1, c1, c2, c3 FROM big;
CHECKSUM TABLE big;
connection analyze;
ANALYZE TABLE big;
SELECT clust_index_size FROM INFORMATION_SCHEMA.INNODB_SYS_TABLESTATS
WHERE name = 'test/big';
connection default;
ROLLBACK;
CHECKSUM TABLE big;
connection analyze;
ANALYZE TABLE big;
SELECT clust_index_size FROM INFORMATION_SCHEMA.INNODB_SYS_TABLESTATS
WHERE name = 'test/big';
connection default;
--source include/wait_all_purged.inc
DROP TABLE t1,t2,t3,t4,big;
# MDEV-14837 Duplicate primary keys are allowed after ADD COLUMN / UPDATE
eval CREATE TABLE t1 (a VARCHAR(1) PRIMARY KEY) $engine;
INSERT INTO t1 SET a='a';
ALTER TABLE t1 ADD COLUMN b INT NOT NULL DEFAULT 0;
UPDATE t1 SET b = 1;
--error ER_DUP_ENTRY
INSERT INTO t1 SET a='a';
SELECT * FROM t1;
DROP TABLE t1;
# MDEV-16065 Assertion failed in btr_pcur_restore_position_func on UPDATE
eval CREATE TABLE t1 (a INT, b VARCHAR(8), PRIMARY KEY(b,a)) $engine;
INSERT INTO t1 VALUES (1,'foo');
ALTER TABLE t1 ADD COLUMN c INT;
UPDATE t1 SET c = 1;
UPDATE t1 SET c = 2;
DROP TABLE t1;
# MDEV-16830 Crash in ALTER TABLE DROP FOREIGN KEY
eval CREATE TABLE t1 (a INT PRIMARY KEY) $engine;
eval CREATE TABLE t2 (b INT PRIMARY KEY, FOREIGN KEY(b) REFERENCES t1(a))
$engine;
INSERT INTO t1 SET a=1;
INSERT INTO t2 SET b=1;
ALTER TABLE t2 ADD COLUMN a INT, DROP FOREIGN KEY t2_ibfk_1;
ALTER TABLE t2 ADD INDEX(a);
--error ER_ALTER_OPERATION_NOT_SUPPORTED_REASON
ALTER TABLE t1 ADD COLUMN b INT, ADD FOREIGN KEY(a) REFERENCES t2(a),
ALGORITHM=INSTANT;
SET foreign_key_checks=0;
ALTER TABLE t1 ADD COLUMN b INT, ADD FOREIGN KEY(a) REFERENCES t2(a),
ALGORITHM=INSTANT;
ALTER TABLE t2 ADD CONSTRAINT fk FOREIGN KEY(b) REFERENCES t1(a),
ALGORITHM=INSTANT;
SET foreign_key_checks=1;
ALTER TABLE t2 COMMENT 'domestic keys only', DROP FOREIGN KEY fk;
ALTER TABLE t1 DROP FOREIGN KEY t1_ibfk_1;
ALTER TABLE t1 ADD COLUMN big BLOB NOT NULL
DEFAULT REPEAT('a', @@GLOBAL.innodb_page_size * .75);
CHECK TABLE t2, t1;
DROP TABLE t2, t1;
#
# MDEV-17483 Insert on delete-marked record can wrongly inherit old values
# for instantly added column
#
eval CREATE TABLE t1 (a INT PRIMARY KEY) $engine;
INSERT INTO t1 SET a = 1;
ALTER TABLE t1 ADD COLUMN b TEXT;
BEGIN;
UPDATE t1 SET b = REPEAT('1', 32768);
UPDATE t1 SET a = 2;
INSERT INTO t1 SET a = 1;
SELECT a,LENGTH(b) FROM t1;
DELETE FROM t1;
COMMIT;
--source include/wait_all_purged.inc
DROP TABLE t1;
dec $format;
}
disconnect analyze;
SELECT variable_value-@old_instant instants
FROM information_schema.global_status
WHERE variable_name = 'innodb_instant_alter_column';
SET GLOBAL innodb_purge_rseg_truncate_frequency= @saved_frequency;
|