3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
6 # May you do good and not evil.
7 # May you find forgiveness for yourself and forgive others.
8 # May you share freely, never taking more than you give.
10 #***********************************************************************
12 # Test cases for generated columns.
15 set testdir [file dirname $argv0]
16 source $testdir/tester.tcl
18 # ticket 830277d9db6c3ba1 on 2019-10-31
19 do_execsql_test gencol1-100 {
20 CREATE TABLE t0(c0 AS(TYPEOF(c1)), c1);
21 INSERT INTO t0(c1) VALUES(0);
22 CREATE TABLE t1(x AS (typeof(y)), y);
23 INSERT INTO t1 SELECT * FROM t0;
33 w INT GENERATED ALWAYS AS (a*10),
34 x TEXT AS (typeof(c)),
35 y TEXT AS (substr(b,a,a+2))
40 w INT GENERATED ALWAYS AS (a*10),
41 x TEXT AS (typeof(c)),
42 y TEXT AS (substr(b,a,a+2)),
50 w INT GENERATED ALWAYS AS (a*10),
52 x TEXT AS (typeof(c)) STORED,
54 y TEXT AS (substr(b,a,a+2)),
60 a INTEGER PRIMARY KEY,
61 w INT GENERATED ALWAYS AS (a*10),
63 x TEXT AS (typeof(c)),
64 y TEXT AS (substr(b,a,a+2)) STORED,
70 w INT GENERATED ALWAYS AS (a*10),
72 x TEXT AS (typeof(c)),
74 y TEXT AS (substr(b,a,a+2)) STORED,
81 w INT GENERATED ALWAYS AS (m*5),
82 m INT AS (a*2) STORED,
84 x TEXT AS (typeof(c)),
86 y TEXT AS (substr(b,m/2,m/2+2)) STORED,
93 w INT GENERATED ALWAYS AS (m*5),
94 m INT AS (a*2) NOT NULL,
96 x TEXT AS (typeof(c)) CHECK (x<>'blank'),
98 y TEXT AS (substr(b,m/2,m/2+2)) STORED,
107 do_execsql_test gencol1-2.$tn.100 {
108 INSERT INTO t1(a,b,c) VALUES(1,'abcdef',5.5),(3,'cantaloupe',NULL);
109 SELECT w, x, y, '|' FROM t1 ORDER BY a;
110 } {10 real abc | 30 null ntalo |}
111 do_execsql_test gencol1-2.$tn.101 {
112 SELECT w, x, y, '|' FROM t1 ORDER BY w;
113 } {10 real abc | 30 null ntalo |}
114 do_execsql_test gencol1-2.$tn.102 {
115 SELECT a FROM t1 WHERE w=30;
117 do_execsql_test gencol1-2.$tn.103 {
118 SELECT a FROM t1 WHERE x='real';
120 do_execsql_test gencol1-2.$tn.104 {
121 SELECT a FROM t1 WHERE y LIKE '%tal%' OR x='real' ORDER BY b;
123 do_execsql_test gencol1-2.$tn.110 {
124 CREATE INDEX t1w ON t1(w);
125 SELECT a FROM t1 WHERE w=10;
127 do_execsql_test gencol1-2.$tn.120 {
128 CREATE INDEX t1x ON t1(x) WHERE w BETWEEN 20 AND 40;
129 SELECT a FROM t1 WHERE x='null' AND w BETWEEN 20 AND 40;
131 do_execsql_test gencol1-2.$tn.121 {
132 SELECT a FROM t1 WHERE x='real';
134 do_execsql_test gencol1-2.$tn.130 {
136 PRAGMA integrity_check;
138 do_execsql_test gencol1-2.$tn.140 {
139 UPDATE t1 SET a=a+100 WHERE w<20;
140 SELECT a, w, '|' FROM t1 ORDER BY w;
141 } {3 30 | 101 1010 |}
142 do_execsql_test gencol1-2.$tn.150 {
143 INSERT INTO t1 VALUES(4,'jambalaya','Chef John'),(15,87719874135,0);
144 SELECT w, x, y, '|' FROM t1 ORDER BY w;
145 } {30 null ntalo | 40 text balaya | 150 integer {} | 1010 real {} |}
148 # 2019-10-31 ticket b9befa4b83a660cc
151 do_execsql_test gencol1-3.100 {
152 PRAGMA foreign_keys = true;
153 CREATE TABLE t0(c0 PRIMARY KEY, c1, c2 AS (c0+c1-c3) REFERENCES t0, c3);
154 INSERT INTO t0 VALUES (0, 0, 0), (11, 5, 5);
155 UPDATE t0 SET c1 = c0, c3 = c0;
156 SELECT *, '|' FROM t0 ORDER BY +c0;
157 } {0 0 0 0 | 11 11 11 11 |}
158 do_catchsql_test gencol1-3.110 {
159 UPDATE t0 SET c1 = c0, c3 = c0+1;
160 } {1 {FOREIGN KEY constraint failed}}
162 # 2019-11-01 ticket c28a01da72f8957c
165 do_execsql_test gencol1-4.100 {
172 PRAGMA foreign_keys = true;
173 INSERT INTO t0(c0,c2,c3) VALUES(0,0,1);
175 do_catchsql_test gencol1-4.110 {
176 REPLACE INTO t0(c0,c2,c3) VALUES(0,0,0),(0,0,0);
177 } {1 {FOREIGN KEY constraint failed}}
179 # 2019-11-01 Problem found while adding new foreign key test cases in TH3.
182 do_execsql_test gencol1-5.100 {
183 PRAGMA foreign_keys=ON;
186 a INTEGER PRIMARY KEY,
192 INSERT INTO t1 VALUES(1,2,3);
193 INSERT INTO t1 VALUES(4,5,6);
194 INSERT INTO t1 VALUES(7,8,9);
196 gcx AS (x+0) REFERENCES t1(a) ON DELETE CASCADE,
201 INSERT INTO t1a VALUES(1, 1);
202 INSERT INTO t1a VALUES(2, 4);
203 INSERT INTO t1a VALUES(3, 7);
204 DELETE FROM t1 WHERE b=5;
205 SELECT id,x,'|' FROM t1a ORDER BY id;
208 do_catchsql_test gencol1-6.10 {
209 DROP TABLE IF EXISTS t0;
210 CREATE TABLE t0(c0 NOT NULL AS(c1), c1);
211 REPLACE INTO t0(c1) VALUES(NULL);
212 } {1 {NOT NULL constraint failed: t0.c0}}
214 # 2019-11-06 ticket https://www.sqlite.org/src/info/2399f5986134f79c
215 # 2019-12-27 ticket https://www.sqlite.org/src/info/5fbc159eeb092130
216 # 2019-12-27 ticket https://www.sqlite.org/src/info/37823501c68a09f9
218 # All of the above tickets deal with NOT NULL ON CONFLICT REPLACE
219 # constraints on tables that have generated columns.
222 do_execsql_test gencol1-7.10 {
223 CREATE TABLE t0 (c0 GENERATED ALWAYS AS (1), c1 UNIQUE, c2 UNIQUE);
224 INSERT INTO t0(c1) VALUES (1);
225 SELECT quote(0 = t0.c2 OR t0.c1 BETWEEN t0.c2 AND 1) FROM t0;
227 do_execsql_test gencol1-7.11 {
229 CREATE TABLE t0(c0 NOT NULL DEFAULT 'xyz', c1 AS(c0) NOT NULL);
230 REPLACE INTO t0(c0) VALUES(NULL);
233 do_execsql_test gencol1-7.12 {
235 CREATE TABLE t0(c0 NOT NULL DEFAULT 'xyz', c1 AS(c0) STORED NOT NULL);
236 REPLACE INTO t0(c0) VALUES(NULL);
239 do_execsql_test gencol1-7.20 {
241 a NOT NULL DEFAULT 'aaa',
243 c NOT NULL DEFAULT 'ccc');
244 REPLACE INTO t1(a,c) VALUES(NULL,NULL);
247 do_execsql_test gencol1-7.21 {
250 a NOT NULL DEFAULT 'aaa',
251 b AS(c) STORED NOT NULL,
252 c NOT NULL DEFAULT 'ccc');
253 REPLACE INTO t1(a,c) VALUES(NULL,NULL);
256 do_execsql_test gencol1-7.30 {
258 a NOT NULL DEFAULT 'aaa',
260 c NOT NULL DEFAULT 'ccc');
261 REPLACE INTO t2(a,c) VALUES(NULL,NULL);
264 do_execsql_test gencol1-7.31 {
267 a NOT NULL DEFAULT 'aaa',
268 b AS(a) STORED NOT NULL,
269 c NOT NULL DEFAULT 'ccc');
270 REPLACE INTO t2(a,c) VALUES(NULL,NULL);
273 do_execsql_test gencol1-7.40 {
274 CREATE TABLE t3(a NOT NULL DEFAULT 123, b AS(a) UNIQUE);
275 REPLACE INTO t3 VALUES(NULL);
278 do_execsql_test gencol1-7.41 {
279 SELECT * FROM t3 WHERE b=123;
281 do_execsql_test gencol1-7.50 {
282 CREATE TABLE t4(a NOT NULL DEFAULT 123, b AS(a*10+4) STORED UNIQUE);
283 REPLACE INTO t4 VALUES(NULL);
286 do_execsql_test gencol1-7.51 {
287 SELECT * FROM t4 WHERE b=1234;
290 # 2019-11-06 ticket 4fc08501f4e56692
291 do_execsql_test gencol1-8.10 {
292 DROP TABLE IF EXISTS t0;
294 c0 AS (('a', 9) < ('b', c1)),
298 INSERT INTO t0 VALUES (0),(99);
301 do_catchsql_test gencol1-8.20 {
302 DROP TABLE IF EXISTS t0;
308 UPDATE t0 SET c0 = NULL;
309 } {1 {generated column loop on "c2"}}
311 # 2019-11-21 Problems in the new generated column logic
312 # reported by Yongheng Chen and Rui Zhong
314 do_execsql_test gencol1-9.10 {
315 PRAGMA foreign_keys=OFF;
316 CREATE TABLE t1(aa , bb AS (17) UNIQUE);
317 INSERT INTO t1 VALUES(17);
319 INSERT INTO t2 VALUES(41);
320 SELECT * FROM t2 JOIN t1 WHERE t1.bb=t1.aa AND t1.bb=17;
322 do_execsql_test gencol1-9.20 {
323 CREATE TABLE t3(aa INT PRIMARY KEY, bb UNIQUE AS(aa));
324 INSERT INTO t3 VALUES(1);
325 SELECT 100, * FROM t3;
326 DELETE FROM t3 WHERE (SELECT bb FROM t3);
327 SELECT 200, * FROM t3;
330 # 2019-12-04 Generated column in a CREATE TABLE IF NOT EXISTS that
331 # does already exist.
334 do_execsql_test gencol1-10.10 {
335 CREATE TABLE t1(aa,bb);
336 CREATE TABLE IF NOT EXISTS t1(aa, bb AS (aa+1));
337 PRAGMA integrity_check;
340 # 2019-12-06 Found by mrigger
343 do_execsql_test gencol1-11.10 {
344 PRAGMA foreign_keys = true;
347 c1 INTEGER PRIMARY KEY,
348 c2 BLOB UNIQUE DEFAULT x'00',
349 c3 BLOB GENERATED ALWAYS AS (1),
350 FOREIGN KEY(c1) REFERENCES t0(c2)
353 do_catchsql_test gencol1-11.20 {
354 INSERT OR REPLACE INTO t0(c0, c1) VALUES (2, 1), (1, 0)
355 } {1 {FOREIGN KEY constraint failed}}
356 do_execsql_test gencol1-11.30 {
360 c1 INTEGER PRIMARY KEY,
361 c3 BLOB GENERATED ALWAYS AS (1),
362 c2 BLOB UNIQUE DEFAULT x'00',
363 FOREIGN KEY(c1) REFERENCES t0(c2)
366 do_catchsql_test gencol1-11.40 {
367 INSERT OR REPLACE INTO t0(c0, c1) VALUES (2, 1), (1, 0)
368 } {1 {FOREIGN KEY constraint failed}}
369 do_execsql_test gencol1-11.50 {
373 c3 BLOB GENERATED ALWAYS AS (1),
374 c1 INTEGER PRIMARY KEY,
375 c2 BLOB UNIQUE DEFAULT x'00',
376 FOREIGN KEY(c1) REFERENCES t0(c2)
379 do_catchsql_test gencol1-11.60 {
380 INSERT OR REPLACE INTO t0(c0, c1) VALUES (2, 1), (1, 0)
381 } {1 {FOREIGN KEY constraint failed}}
382 do_execsql_test gencol1-11.70 {
385 c3 BLOB GENERATED ALWAYS AS (1),
387 c1 INTEGER PRIMARY KEY,
388 c2 BLOB UNIQUE DEFAULT x'00',
389 FOREIGN KEY(c1) REFERENCES t0(c2)
392 do_catchsql_test gencol1-11.80 {
393 INSERT OR REPLACE INTO t0(c0, c1) VALUES (2, 1), (1, 0)
394 } {1 {FOREIGN KEY constraint failed}}
396 # 2019-12-09 ticket bd8c280671ba44a7
397 # With generated columns, the sqlite3ExprGetColumnOfTable() routine might
398 # generate a code sequence that does not end with OP_Column. So check to
399 # make sure that the last instruction generated is an OP_column prior to
400 # applying the OPFLAG_TYPEOFARG optimization to NOT NULL checks in the
401 # PRAGMA integrity_check code.
404 do_execsql_test gencol1-12.10 {
405 CREATE TABLE t0 (c0, c1 NOT NULL AS (c0==0));
406 INSERT INTO t0(c0) VALUES (0);
407 PRAGMA integrity_check;
410 # 2019-12-09 bug report from Yongheng Chen
411 # Ensure that the SrcList_item.colUsed field is set correctly when a
412 # generated column appears in the USING clause of a join.
414 do_execsql_test gencol1-13.10 {
415 CREATE TABLE t1(x, y AS(x+1));
416 INSERT INTO t1 VALUES(10);
417 SELECT y FROM t1 JOIN t1 USING (y,y);
419 do_execsql_test gencol1-13.11 {
420 SELECT 123 FROM t1 JOIN t1 USING (x);
422 do_execsql_test gencol1-13.11 {
423 SELECT 456 FROM t1 JOIN t1 USING (x,x);
425 do_execsql_test gencol1-13.20 {
426 CREATE INDEX t1y ON t1(y);
427 SELECT y FROM t1 JOIN t1 USING (y,y);
429 do_execsql_test gencol1-13.21 {
430 CREATE INDEX t1x ON t1(x);
431 SELECT 123 FROM t1 JOIN t1 USING (x);
433 do_execsql_test gencol1-13.22 {
434 SELECT 456 FROM t1 JOIN t1 USING (x,x);
437 # 2019-12-14 ticket b439bfcfb7deedc6
440 do_execsql_test gencol1-14.10 {
441 CREATE TABLE t0(c0 AS(1 >= 1), c1 UNIQUE AS(TYPEOF(c0)), c2);
442 INSERT INTO t0 VALUES(0);
446 do_catchsql_test gencol1-14.10 {
447 INSERT INTO t0 VALUES(2);
448 } {1 {UNIQUE constraint failed: t0.c1}}
450 # 2019-12-14 gramfuzz1 find
451 # The schema is malformed in that it has a subquery on a generated
452 # column expression. This will be loaded if writable_schema=ON. SQLite
453 # must not use such an expression during code generation as the code generator
454 # will add bits of content to the expression tree that might be allocated
455 # from lookaside. But the schema is not tied to a particular database
456 # connection, so the use of lookaside memory is prohibited. The fix
457 # is to change the generated column expression to NULL before adding it
461 do_test gencol1-15.10 {
463 db deserialize [decode_hexdb {
464 | size 8192 pagesize 4096 filename c27.db
466 | 0: 53 51 4c 69 74 65 20 66 6f 72 6d 61 74 20 33 00 SQLite format 3.
467 | 16: 10 00 01 01 00 40 20 20 00 00 00 01 00 00 00 02 .....@ ........
468 | 32: 00 00 00 00 00 00 00 00 00 00 00 01 00 00 00 04 ................
469 | 48: 00 00 00 00 00 00 00 00 00 00 00 01 00 00 00 00 ................
470 | 80: 00 00 00 00 00 00 00 00 00 00 00 00 00 00 00 01 ................
471 | 96: 00 2e 3f d8 0d 00 00 00 01 0f ba 00 0f ba 00 00 ..?.............
472 | 4016: 00 00 00 00 00 00 00 00 00 00 44 01 06 17 11 11 ..........D.....
473 | 4032: 01 75 74 61 62 6c 65 74 31 74 31 02 43 52 45 41 .utablet1t1.CREA
474 | 4048: 54 45 20 54 41 42 4c 45 20 74 31 28 61 20 49 4e TE TABLE t1(a IN
475 | 4064: 54 2c 20 62 20 41 53 28 28 56 41 4c 55 45 53 28 T, b AS((VALUES(
476 | 4080: 31 29 29 20 49 53 20 75 6e 6b 6e 6f 77 6e 29 29 1)) IS unknown))
478 | 0: 0d 00 00 00 00 10 00 00 00 00 00 00 00 00 00 00 ................
481 do_execsql_test gencol1-15.20 {
482 PRAGMA writable_schema=ON;
483 REPLACE INTO t1 VALUES(9);
484 SELECT a, quote(b) FROM t1
487 # 2019-12-16 ticket 3b84b42943644d6f
488 # When a table is the right table of a LEFT JOIN and the ON clause is
489 # false, make sure any generated columns evaluate to NULL.
491 do_execsql_test gencol1-16.10 {
493 CREATE TABLE t1(c1, c2 AS(1));
494 INSERT INTO t0 VALUES(0);
495 SELECT c0, c1, c2 FROM t0 LEFT JOIN t1;
497 do_execsql_test gencol1-16.20 {
499 CREATE TABLE t1(c1, c2 AS (c1 ISNULL));
500 SELECT c0, c1, c2 FROM t0 LEFT JOIN t1;
502 do_execsql_test gencol1-16.30 {
503 INSERT INTO t1(c1) VALUES(1),(NULL);
506 do_execsql_test gencol1-16.40 {
507 SELECT c0, c1, c2 FROM t0 LEFT JOIN t1 ON c0=c1;
510 # 2019-12-20 ticket e0a8120553f4b082
511 # Generated columns with REAL affinity need to have an OP_RealAffinity
512 # opcode applied, even when the column value is extracted from an index.
515 do_execsql_test gencol1-17.10 {
516 CREATE TABLE t0(c0 REAL AS(1) UNIQUE, c1 INT);
517 INSERT INTO t0 VALUES('');
518 SELECT quote(c0), quote(c1) from t0;
520 do_execsql_test gencol1-17.20 {
521 SELECT *, (1 BETWEEN CAST(t0.c0 AS TEXT) AND t0.c0) FROM t0;
523 do_execsql_test gencol1-17.30 {
524 SELECT * FROM t0 WHERE (1 BETWEEN CAST(t0.c0 AS TEXT) AND t0.c0);
526 do_execsql_test gencol1-17.40 {
527 CREATE TABLE t1(a TEXT AS(b) COLLATE nocase, b TEXT, c INT, d DEFAULT 1);
528 INSERT INTO t1(b,c) VALUES('abc',11),('DEF',22),('ghi',33);
529 SELECT a FROM t1 WHERE b='DEF' AND a='def';
531 do_execsql_test gencol1-17.50 {
532 CREATE INDEX t1bca ON t1(b,c,a);
533 SELECT a FROM t1 WHERE b='DEF' AND a='def';
536 # 2019-12-26 ticket ec8abb025e78f40c
537 # An index on a virtual column with a constant value (why would anybody
538 # ever do such a thing?) can cause problems for a one-pass DELETE.
541 do_execsql_test gencol1-18.10 {
542 CREATE TABLE t0(c0 UNIQUE AS(0), c1, c2);
543 INSERT INTO t0(c1) VALUES(0);
546 do_execsql_test gencol1-18.20 {
547 UPDATE t0 SET c1=0, c2=0 WHERE c0>=0;
551 # 2019-12-27 ticket de4b04149b9fdeae
554 do_catchsql_test gencol1-19.10 {
558 FOREIGN KEY(c0) REFERENCES t0(c1)
560 INSERT INTO t0(c1) VALUES(0.16334143182538696), (0);
561 } {1 {UNIQUE constraint failed: t0.c0}}
563 # 2020-06-29 forum bug report.
564 # https://sqlite.org/forum/forumpost/73b9a8ccfb
566 do_execsql_test gencol1-20.1 {
567 CREATE TEMPORARY TABLE tab (
568 prim DATE PRIMARY KEY,
575 INSERT INTO tab (prim, a, b) VALUES ('2001-01-01', 0, 0);
576 -- Check that each column is 0 like I expect
578 } {2001-01-01 0 0 0 {}}
579 do_execsql_test gencol1-20.2 {
580 -- Do an UPSERT on the b column
581 INSERT INTO tab (prim, b)
582 VALUES ('2001-01-01',5)
583 ON CONFLICT(prim) DO UPDATE SET b=excluded.b;
584 -- Now b is NULL rather than 5
586 } {2001-01-01 0 0 5 {}}