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 #***********************************************************************
11 # This file implements regression tests for SQLite library.
13 # This file implements tests for miscellanous features that were
14 # left out of other test files.
16 # $Id: misc2.test,v 1.28 2007/09/12 17:01:45 danielk1977 Exp $
18 set testdir [file dirname $argv0]
19 source $testdir/tester.tcl
21 # The tests in this file were written before SQLite supported recursive
22 # trigger invocation, and some tests depend on that to pass. So disable
23 # recursive triggers for this file.
24 catchsql { pragma recursive_triggers = off }
27 # Test for ticket #360
31 CREATE TABLE FOO(bar integer);
32 CREATE TRIGGER foo_insert BEFORE INSERT ON foo BEGIN
33 SELECT CASE WHEN (NOT new.bar BETWEEN 0 AND 20)
34 THEN raise(rollback, 'aiieee') END;
36 INSERT INTO foo(bar) VALUES (1);
41 INSERT INTO foo(bar) VALUES (111);
46 # Make sure ROWID works on a view and a subquery. Ticket #364
50 CREATE TABLE t1(a,b,c);
51 INSERT INTO t1 VALUES(1,2,3);
52 CREATE TABLE t2(a,b,c);
53 INSERT INTO t2 VALUES(7,8,9);
57 ifcapable allow_rowid_in_view {
58 do_catchsql_test misc2-2.2 {
59 SELECT rowid, * FROM (SELECT * FROM t1, t2);
60 } {0 {{} 1 2 3 7 8 9}}
62 do_catchsql_test misc2-2.2 {
63 SELECT rowid, * FROM (SELECT * FROM t1, t2);
64 } {1 {no such column: rowid}}
66 do_catchsql_test misc2-2.2b {
67 SELECT 'rowid', * FROM (SELECT * FROM t1, t2);
68 } {0 {rowid 1 2 3 7 8 9}}
72 ifcapable allow_rowid_in_view {
73 do_catchsql_test misc2-2.3 {
74 CREATE VIEW v1 AS SELECT * FROM t1, t2;
75 SELECT rowid, * FROM v1;
76 } {0 {{} 1 2 3 7 8 9}}
78 do_catchsql_test misc2-2.3 {
79 CREATE VIEW v1 AS SELECT * FROM t1, t2;
80 SELECT rowid, * FROM v1;
81 } {1 {no such column: rowid}}
85 do_catchsql_test misc2-2.3b {
86 SELECT 'rowid', * FROM v1;
87 } {0 {rowid 1 2 3 7 8 9}}
90 # Ticket #2002 and #1952.
94 SELECT * FROM (SELECT a, b AS 'a', c AS 'a', 4 AS 'a' FROM t1)
96 } {a 1 a:1 2 a:2 3 a:3 4}
99 # Check name binding precedence. Ticket #387
103 SELECT t1.b+t2.b AS a, t1.a, t2.a FROM t1, t2 WHERE a==10
105 } {1 {ambiguous column name: a}}
107 # Make sure 32-bit integer overflow is handled properly in queries.
112 INSERT INTO t1 VALUES(4000000000,'a','b');
113 SELECT a FROM t1 WHERE a>1;
118 INSERT INTO t1 VALUES(2147483648,'b2','c2');
119 INSERT INTO t1 VALUES(2147483647,'b3','c3');
120 SELECT a FROM t1 WHERE a>2147483647;
122 } {4000000000 2147483648}
125 SELECT a FROM t1 WHERE a<2147483648;
130 SELECT a FROM t1 WHERE a<=2147483648;
132 } {1 2147483648 2147483647}
135 SELECT a FROM t1 WHERE a<10000000000;
137 } {1 4000000000 2147483648 2147483647}
140 SELECT a FROM t1 WHERE a<1000000000000 ORDER BY 1;
142 } {1 2147483647 2147483648 4000000000}
144 # There were some issues with expanding a SrcList object using a call
145 # to sqliteSrcListAppend() if the SrcList had previously been duplicated
146 # using a call to sqliteSrcListDup(). Ticket #416. The following test
147 # makes sure the problem has been fixed.
154 SELECT x1.b AS p, x2.b AS q FROM x AS x1, x AS x2 WHERE x1.a=x2.a;
156 SELECT y1.p, y2.p FROM y AS y1, y AS y2 WHERE y1.q=y2.q;
162 # Make sure we can open a database with an empty filename. What this
163 # does is store the database in a temporary file that is deleted when
164 # the database is closed. Ticket #432.
170 CREATE TABLE t1(a,b);
171 INSERT INTO t1 VALUES(1,2);
176 # Make sure we get an error message (not a segfault) on an attempt to
177 # update a table from within the callback of a select on that same
180 # 2006-08-16: This has changed. It is now permitted to update
181 # the table being SELECTed from within the callback of the query.
190 INSERT INTO t1 VALUES(1);
191 INSERT INTO t1 VALUES(2);
192 INSERT INTO t1 VALUES(3);
198 db eval {SELECT rowid FROM t1} {} {
199 db eval "DELETE FROM t1 WHERE rowid=$rowid"
205 execsql {SELECT * FROM t1}
210 INSERT INTO t1 VALUES(1);
211 INSERT INTO t1 VALUES(2);
212 INSERT INTO t1 VALUES(3);
213 INSERT INTO t1 VALUES(4);
215 db eval {SELECT rowid, x FROM t1} {
217 db eval {DELETE FROM t1 WHERE rowid=$rowid}
220 execsql {SELECT * FROM t1}
225 INSERT INTO t1 VALUES(1);
226 INSERT INTO t1 VALUES(2);
227 INSERT INTO t1 VALUES(3);
228 INSERT INTO t1 VALUES(4);
230 db eval {SELECT rowid, x FROM t1} {
232 db eval {DELETE FROM t1 WHERE rowid=$rowid+1}
235 execsql {SELECT * FROM t1}
240 INSERT INTO t1 VALUES(1);
241 INSERT INTO t1 VALUES(2);
242 INSERT INTO t1 VALUES(3);
243 INSERT INTO t1 VALUES(4);
245 db eval {SELECT rowid, x FROM t1} {
247 db eval {DELETE FROM t1}
250 execsql {SELECT * FROM t1}
255 INSERT INTO t1 VALUES(1);
256 INSERT INTO t1 VALUES(2);
257 INSERT INTO t1 VALUES(3);
258 INSERT INTO t1 VALUES(4);
260 db eval {SELECT rowid, x FROM t1} {
262 db eval {UPDATE t1 SET x=x+100 WHERE rowid=$rowid}
265 execsql {SELECT * FROM t1}
270 INSERT INTO t1 VALUES(1);
272 db eval {SELECT rowid, x FROM t1} {
274 db eval {INSERT INTO t1 VALUES($x+1)}
277 execsql {SELECT * FROM t1}
278 } {1 2 3 4 5 6 7 8 9 10}
280 # Repeat the tests 7.1 through 7.8 about but this time do the SELECTs
281 # in reverse order so that we exercise the sqlite3BtreePrev() routine
282 # instead of sqlite3BtreeNext()
290 INSERT INTO t1 VALUES(1);
291 INSERT INTO t1 VALUES(2);
292 INSERT INTO t1 VALUES(3);
298 db eval {SELECT rowid FROM t1 ORDER BY rowid DESC} {} {
299 db eval "DELETE FROM t1 WHERE rowid=$rowid"
305 execsql {SELECT * FROM t1}
310 INSERT INTO t1 VALUES(1);
311 INSERT INTO t1 VALUES(2);
312 INSERT INTO t1 VALUES(3);
313 INSERT INTO t1 VALUES(4);
315 db eval {SELECT rowid, x FROM t1 ORDER BY rowid DESC} {
317 db eval {DELETE FROM t1 WHERE rowid=$rowid}
320 execsql {SELECT * FROM t1}
325 INSERT INTO t1 VALUES(1);
326 INSERT INTO t1 VALUES(2);
327 INSERT INTO t1 VALUES(3);
328 INSERT INTO t1 VALUES(4);
330 db eval {SELECT rowid, x FROM t1} {
332 db eval {DELETE FROM t1 WHERE rowid=$rowid+1}
335 execsql {SELECT * FROM t1}
340 INSERT INTO t1 VALUES(1);
341 INSERT INTO t1 VALUES(2);
342 INSERT INTO t1 VALUES(3);
343 INSERT INTO t1 VALUES(4);
345 db eval {SELECT rowid, x FROM t1 ORDER BY rowid DESC} {
347 db eval {DELETE FROM t1}
350 execsql {SELECT * FROM t1}
355 INSERT INTO t1 VALUES(1);
356 INSERT INTO t1 VALUES(2);
357 INSERT INTO t1 VALUES(3);
358 INSERT INTO t1 VALUES(4);
360 db eval {SELECT rowid, x FROM t1 ORDER BY rowid DESC} {
362 db eval {UPDATE t1 SET x=x+100 WHERE rowid=$rowid}
365 execsql {SELECT * FROM t1}
370 INSERT INTO t1(rowid,x) VALUES(10,10);
372 db eval {SELECT rowid, x FROM t1 ORDER BY rowid DESC} {
374 db eval {INSERT INTO t1(rowid,x) VALUES($x-1,$x-1)}
377 execsql {SELECT * FROM t1}
378 } {1 2 3 4 5 6 7 8 9 10}
384 catchsql { pragma recursive_triggers = off }
386 # Ticket #453. If the SQL ended with "-", the tokenizer was calling that
387 # an incomplete token, which caused problem. The solution was to just call
392 } {1 {near "-": syntax error}}
394 # Ticket #513. Make sure the VDBE stack does not grow on a 3-way join.
400 CREATE TABLE counts(n INTEGER PRIMARY KEY);
401 INSERT INTO counts VALUES(0);
402 INSERT INTO counts VALUES(1);
403 INSERT INTO counts SELECT n+2 FROM counts;
404 INSERT INTO counts SELECT n+4 FROM counts;
405 INSERT INTO counts SELECT n+8 FROM counts;
408 CREATE TEMP TABLE x AS
409 SELECT dim1.n, dim2.n, dim3.n
410 FROM counts AS dim1, counts AS dim2, counts AS dim3
411 WHERE dim1.n<10 AND dim2.n<10 AND dim3.n<10;
413 SELECT count(*) FROM x;
419 CREATE TEMP TABLE x AS
420 SELECT dim1.n, dim2.n, dim3.n
421 FROM counts AS dim1, counts AS dim2, counts AS dim3
422 WHERE dim1.n>=6 AND dim2.n>=6 AND dim3.n>=6;
424 SELECT count(*) FROM x;
430 CREATE TEMP TABLE x AS
431 SELECT dim1.n, dim2.n, dim3.n, dim4.n
432 FROM counts AS dim1, counts AS dim2, counts AS dim3, counts AS dim4
433 WHERE dim1.n<5 AND dim2.n<5 AND dim3.n<5 AND dim4.n<5;
435 SELECT count(*) FROM x;
440 # Ticket #1229. Sometimes when a "NEW.X" appears in a SELECT without
441 # a FROM clause deep within a trigger, the code generator is unable to
442 # trace the NEW.X back to an original table and thus figure out its
445 # The SQL code below was causing a segfault.
447 ifcapable subquery&&trigger {
450 CREATE TABLE t1229(x);
451 CREATE TRIGGER r1229 BEFORE INSERT ON t1229 BEGIN
452 INSERT INTO t1229 SELECT y FROM (SELECT new.x y);
454 INSERT INTO t1229 VALUES(1);