# 2001 September 15. # # The author disclaims copyright to this source code. In place of # a legal notice, here is a blessing: # # May you do good and not evil. # May you find forgiveness for yourself and forgive others. # May you share freely, never taking more than you give. # #*********************************************************************** # This file implements regression tests for SQLite library. # # This file implements tests for miscellanous features that were # left out of other test files. # # $Id: misc1.test,v 1.42 2007/11/05 14:58:23 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl # Mimic the SQLite 2 collation type NUMERIC. db collate numeric numeric_collate proc numeric_collate {lhs rhs} { if {$lhs == $rhs} {return 0} return [expr ($lhs>$rhs)?1:-1] } # Mimic the SQLite 2 collation type TEXT. db collate text text_collate proc numeric_collate {lhs rhs} { return [string compare $lhs $rhs] } # Test the creation and use of tables that have a large number # of columns. # do_test misc1-1.1 { set cmd "CREATE TABLE manycol(x0 text" for {set i 1} {$i<=99} {incr i} { append cmd ",x$i text" } append cmd ")"; execsql $cmd set cmd "INSERT INTO manycol VALUES(0" for {set i 1} {$i<=99} {incr i} { append cmd ",$i" } append cmd ")"; execsql $cmd execsql "SELECT x99 FROM manycol" } 99 do_test misc1-1.2 { execsql {SELECT x0, x10, x25, x50, x75 FROM manycol} } {0 10 25 50 75} do_test misc1-1.3.1 { for {set j 100} {$j<=1000} {incr j 100} { set cmd "INSERT INTO manycol VALUES($j" for {set i 1} {$i<=99} {incr i} { append cmd ",[expr {$i+$j}]" } append cmd ")" execsql $cmd } execsql {SELECT x50 FROM manycol ORDER BY x80+0} } {50 150 250 350 450 550 650 750 850 950 1050} do_test misc1-1.3.2 { execsql {SELECT x50 FROM manycol ORDER BY x80} } {1050 150 250 350 450 550 650 750 50 850 950} do_test misc1-1.4 { execsql {SELECT x75 FROM manycol WHERE x50=350} } 375 do_test misc1-1.5 { execsql {SELECT x50 FROM manycol WHERE x99=599} } 550 do_test misc1-1.6 { execsql {CREATE INDEX manycol_idx1 ON manycol(x99)} execsql {SELECT x50 FROM manycol WHERE x99=899} } 850 do_test misc1-1.7 { execsql {SELECT count(*) FROM manycol} } 11 do_test misc1-1.8 { execsql {DELETE FROM manycol WHERE x98=1234} execsql {SELECT count(*) FROM manycol} } 11 do_test misc1-1.9 { execsql {DELETE FROM manycol WHERE x98=998} execsql {SELECT count(*) FROM manycol} } 10 do_test misc1-1.10 { execsql {DELETE FROM manycol WHERE x99=500} execsql {SELECT count(*) FROM manycol} } 10 do_test misc1-1.11 { execsql {DELETE FROM manycol WHERE x99=599} execsql {SELECT count(*) FROM manycol} } 9 # Check GROUP BY expressions that name two or more columns. # do_test misc1-2.1 { execsql { BEGIN TRANSACTION; CREATE TABLE agger(one text, two text, three text, four text); INSERT INTO agger VALUES(1, 'one', 'hello', 'yes'); INSERT INTO agger VALUES(2, 'two', 'howdy', 'no'); INSERT INTO agger VALUES(3, 'thr', 'howareya', 'yes'); INSERT INTO agger VALUES(4, 'two', 'lothere', 'yes'); INSERT INTO agger VALUES(5, 'one', 'atcha', 'yes'); INSERT INTO agger VALUES(6, 'two', 'hello', 'no'); COMMIT } execsql {SELECT count(*) FROM agger} } 6 do_test misc1-2.2 { execsql {SELECT sum(one), two, four FROM agger GROUP BY two, four ORDER BY sum(one) desc} } {8 two no 6 one yes 4 two yes 3 thr yes} do_test misc1-2.3 { execsql {SELECT sum((one)), (two), (four) FROM agger GROUP BY (two), (four) ORDER BY sum(one) desc} } {8 two no 6 one yes 4 two yes 3 thr yes} # Here's a test for a bug found by Joel Lucsy. The code below # was causing an assertion failure. # do_test misc1-3.1 { set r [execsql { CREATE TABLE t1(a); INSERT INTO t1 VALUES('hi'); PRAGMA full_column_names=on; SELECT rowid, * FROM t1; }] lindex $r 1 } {hi} # Here's a test for yet another bug found by Joel Lucsy. The code # below was causing an assertion failure. # do_test misc1-4.1 { execsql { BEGIN; CREATE TABLE t2(a); INSERT INTO t2 VALUES('This is a long string to use up a lot of disk -'); UPDATE t2 SET a=a||a||a||a; INSERT INTO t2 SELECT '1 - ' || a FROM t2; INSERT INTO t2 SELECT '2 - ' || a FROM t2; INSERT INTO t2 SELECT '3 - ' || a FROM t2; INSERT INTO t2 SELECT '4 - ' || a FROM t2; INSERT INTO t2 SELECT '5 - ' || a FROM t2; INSERT INTO t2 SELECT '6 - ' || a FROM t2; COMMIT; SELECT count(*) FROM t2; } } {64} # Make sure we actually see a semicolon or end-of-file in the SQL input # before executing a command. Thus if "WHERE" is misspelled on an UPDATE, # the user won't accidently update every record. # do_test misc1-5.1 { catchsql { CREATE TABLE t3(a,b); INSERT INTO t3 VALUES(1,2); INSERT INTO t3 VALUES(3,4); UPDATE t3 SET a=0 WHEREwww b=2; } } {1 {near "WHEREwww": syntax error}} do_test misc1-5.2 { execsql { SELECT * FROM t3 ORDER BY a; } } {1 2 3 4} # Certain keywords (especially non-standard keywords like "REPLACE") can # also be used as identifiers. The way this works in the parser is that # the parser first detects a syntax error, the error handling routine # sees that the special keyword caused the error, then replaces the keyword # with "ID" and tries again. # # Check the operation of this logic. # do_test misc1-6.1 { catchsql { CREATE TABLE t4( abort, asc, begin, cluster, conflict, copy, delimiters, desc, end, explain, fail, ignore, key, offset, pragma, replace, temp, vacuum, view ); } } {0 {}} do_test misc1-6.2 { catchsql { INSERT INTO t4 VALUES(1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19); } } {0 {}} do_test misc1-6.3 { execsql { SELECT * FROM t4 } } {1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19} do_test misc1-6.4 { execsql { SELECT abort+asc,max(key,pragma,temp) FROM t4 } } {3 17} # Test for multi-column primary keys, and for multiple primary keys. # do_test misc1-7.1 { catchsql { CREATE TABLE error1( a TYPE PRIMARY KEY, b TYPE PRIMARY KEY ); } } {1 {table "error1" has more than one primary key}} do_test misc1-7.2 { catchsql { CREATE TABLE error1( a INTEGER PRIMARY KEY, b TYPE PRIMARY KEY ); } } {1 {table "error1" has more than one primary key}} do_test misc1-7.3 { execsql { CREATE TABLE t5(a,b,c,PRIMARY KEY(a,b)); INSERT INTO t5 VALUES(1,2,3); SELECT * FROM t5 ORDER BY a; } } {1 2 3} do_test misc1-7.4 { catchsql { INSERT INTO t5 VALUES(1,2,4); } } {1 {columns a, b are not unique}} do_test misc1-7.5 { catchsql { INSERT INTO t5 VALUES(0,2,4); } } {0 {}} do_test misc1-7.6 { execsql { SELECT * FROM t5 ORDER BY a; } } {0 2 4 1 2 3} do_test misc1-8.1 { catchsql { SELECT *; } } {1 {no tables specified}} do_test misc1-8.2 { catchsql { SELECT t1.*; } } {1 {no such table: t1}} execsql { DROP TABLE t1; DROP TABLE t2; DROP TABLE t3; DROP TABLE t4; } # 64-bit integers are represented exactly. # do_test misc1-9.1 { catchsql { CREATE TABLE t1(a unique not null, b unique not null); INSERT INTO t1 VALUES('a',1234567890123456789); INSERT INTO t1 VALUES('b',1234567891123456789); INSERT INTO t1 VALUES('c',1234567892123456789); SELECT * FROM t1; } } {0 {a 1234567890123456789 b 1234567891123456789 c 1234567892123456789}} # A WHERE clause is not allowed to contain more than 99 terms. Check to # make sure this limit is enforced. # # 2005-07-16: There is no longer a limit on the number of terms in a # WHERE clause. But keep these tests just so that we have some tests # that use a large number of terms in the WHERE clause. # do_test misc1-10.0 { execsql {SELECT count(*) FROM manycol} } {9} do_test misc1-10.1 { set ::where {WHERE x0>=0} for {set i 1} {$i<=99} {incr i} { append ::where " AND x$i<>0" } catchsql "SELECT count(*) FROM manycol $::where" } {0 9} do_test misc1-10.2 { catchsql "SELECT count(*) FROM manycol $::where AND rowid>0" } {0 9} do_test misc1-10.3 { regsub "x0>=0" $::where "x0=0" ::where catchsql "DELETE FROM manycol $::where" } {0 {}} do_test misc1-10.4 { execsql {SELECT count(*) FROM manycol} } {8} do_test misc1-10.5 { catchsql "DELETE FROM manycol $::where AND rowid>0" } {0 {}} do_test misc1-10.6 { execsql {SELECT x1 FROM manycol WHERE x0=100} } {101} do_test misc1-10.7 { regsub "x0=0" $::where "x0=100" ::where catchsql "UPDATE manycol SET x1=x1+1 $::where" } {0 {}} do_test misc1-10.8 { execsql {SELECT x1 FROM manycol WHERE x0=100} } {102} do_test misc1-10.9 { catchsql "UPDATE manycol SET x1=x1+1 $::where AND rowid>0" } {0 {}} do_test misc1-10.10 { execsql {SELECT x1 FROM manycol WHERE x0=100} } {103} # Make sure the initialization works even if a database is opened while # another process has the database locked. # # Update for v3: The BEGIN doesn't lock the database so the schema is read # and the SELECT returns successfully. do_test misc1-11.1 { execsql {BEGIN} execsql {UPDATE t1 SET a=0 WHERE 0} sqlite3 db2 test.db set rc [catch {db2 eval {SELECT count(*) FROM t1}} msg] lappend rc $msg # v2 result: {1 {database is locked}} } {0 3} do_test misc1-11.2 { execsql {COMMIT} set rc [catch {db2 eval {SELECT count(*) FROM t1}} msg] db2 close lappend rc $msg } {0 3} # Make sure string comparisons really do compare strings in format4+. # Similar tests in the format3.test file show that for format3 and earlier # all comparisions where numeric if either operand looked like a number. # do_test misc1-12.1 { execsql {SELECT '0'=='0.0'} } {0} do_test misc1-12.2 { execsql {SELECT '0'==0.0} } {0} do_test misc1-12.3 { execsql {SELECT '12345678901234567890'=='12345678901234567891'} } {0} do_test misc1-12.4 { execsql { CREATE TABLE t6(a INT UNIQUE, b TEXT UNIQUE); INSERT INTO t6 VALUES('0','0.0'); SELECT * FROM t6; } } {0 0.0} ifcapable conflict { do_test misc1-12.5 { execsql { INSERT OR IGNORE INTO t6 VALUES(0.0,'x'); SELECT * FROM t6; } } {0 0.0} do_test misc1-12.6 { execsql { INSERT OR IGNORE INTO t6 VALUES('y',0); SELECT * FROM t6; } } {0 0.0 y 0} } do_test misc1-12.7 { execsql { CREATE TABLE t7(x INTEGER, y TEXT, z); INSERT INTO t7 VALUES(0,0,1); INSERT INTO t7 VALUES(0.0,0,2); INSERT INTO t7 VALUES(0,0.0,3); INSERT INTO t7 VALUES(0.0,0.0,4); SELECT DISTINCT x, y FROM t7 ORDER BY z; } } {0 0 0 0.0} do_test misc1-12.8 { execsql { SELECT min(z), max(z), count(z) FROM t7 GROUP BY x ORDER BY 1; } } {1 4 4} do_test misc1-12.9 { execsql { SELECT min(z), max(z), count(z) FROM t7 GROUP BY y ORDER BY 1; } } {1 2 2 3 4 2} # This used to be an error. But we changed the code so that arbitrary # identifiers can be used as a collating sequence. Collation is by text # if the identifier contains "text", "blob", or "clob" and is numeric # otherwise. # # Update: In v3, it is an error again. # #do_test misc1-12.10 { # catchsql { # SELECT * FROM t6 ORDER BY a COLLATE unknown; # } #} {0 {0 0 y 0}} do_test misc1-12.11 { execsql { CREATE TABLE t8(x TEXT COLLATE numeric, y INTEGER COLLATE text, z); INSERT INTO t8 VALUES(0,0,1); INSERT INTO t8 VALUES(0.0,0,2); INSERT INTO t8 VALUES(0,0.0,3); INSERT INTO t8 VALUES(0.0,0.0,4); SELECT DISTINCT x, y FROM t8 ORDER BY z; } } {0 0 0.0 0} do_test misc1-12.12 { execsql { SELECT min(z), max(z), count(z) FROM t8 GROUP BY x ORDER BY 1; } } {1 3 2 2 4 2} do_test misc1-12.13 { execsql { SELECT min(z), max(z), count(z) FROM t8 GROUP BY y ORDER BY 1; } } {1 4 4} # There was a problem with realloc() in the OP_MemStore operation of # the VDBE. A buffer was being reallocated but some pointers into # the old copy of the buffer were not being moved over to the new copy. # The following code tests for the problem. # ifcapable subquery { do_test misc1-13.1 { execsql { CREATE TABLE t9(x,y); INSERT INTO t9 VALUES('one',1); INSERT INTO t9 VALUES('two',2); INSERT INTO t9 VALUES('three',3); INSERT INTO t9 VALUES('four',4); INSERT INTO t9 VALUES('five',5); INSERT INTO t9 VALUES('six',6); INSERT INTO t9 VALUES('seven',7); INSERT INTO t9 VALUES('eight',8); INSERT INTO t9 VALUES('nine',9); INSERT INTO t9 VALUES('ten',10); INSERT INTO t9 VALUES('eleven',11); SELECT y FROM t9 WHERE x=(SELECT x FROM t9 WHERE y=1) OR x=(SELECT x FROM t9 WHERE y=2) OR x=(SELECT x FROM t9 WHERE y=3) OR x=(SELECT x FROM t9 WHERE y=4) OR x=(SELECT x FROM t9 WHERE y=5) OR x=(SELECT x FROM t9 WHERE y=6) OR x=(SELECT x FROM t9 WHERE y=7) OR x=(SELECT x FROM t9 WHERE y=8) OR x=(SELECT x FROM t9 WHERE y=9) OR x=(SELECT x FROM t9 WHERE y=10) OR x=(SELECT x FROM t9 WHERE y=11) OR x=(SELECT x FROM t9 WHERE y=12) OR x=(SELECT x FROM t9 WHERE y=13) OR x=(SELECT x FROM t9 WHERE y=14) ; } } {1 2 3 4 5 6 7 8 9 10 11} } # Make sure a database connection still works after changing the # working directory. # do_test misc1-14.1 { file mkdir tempdir cd tempdir execsql {BEGIN} file exists ./test.db-journal } {0} do_test misc1-14.2a { execsql {UPDATE t1 SET a=a||'x' WHERE 0} file exists ../test.db-journal } {0} do_test misc1-14.2b { execsql {UPDATE t1 SET a=a||'y' WHERE 1} file exists ../test.db-journal } {1} do_test misc1-14.3 { cd .. forcedelete tempdir execsql {COMMIT} file exists ./test.db-journal } {0} # A failed create table should not leave the table in the internal # data structures. Ticket #238. # do_test misc1-15.1.1 { catchsql { CREATE TABLE t10 AS SELECT c1; } } {1 {no such column: c1}} do_test misc1-15.1.2 { catchsql { CREATE TABLE t10 AS SELECT t9.c1; } } {1 {no such column: t9.c1}} do_test misc1-15.1.3 { catchsql { CREATE TABLE t10 AS SELECT main.t9.c1; } } {1 {no such column: main.t9.c1}} do_test misc1-15.2 { catchsql { CREATE TABLE t10 AS SELECT 1; } # The bug in ticket #238 causes the statement above to fail with # the error "table t10 alread exists" } {0 {}} # Test for memory leaks when a CREATE TABLE containing a primary key # fails. Ticket #249. # do_test misc1-16.1 { catchsql {SELECT name FROM sqlite_master LIMIT 1} catchsql { CREATE TABLE test(a integer, primary key(a)); } } {0 {}} do_test misc1-16.2 { catchsql { CREATE TABLE test(a integer, primary key(a)); } } {1 {table test already exists}} do_test misc1-16.3 { catchsql { CREATE TABLE test2(a text primary key, b text, primary key(a,b)); } } {1 {table "test2" has more than one primary key}} do_test misc1-16.4 { execsql { INSERT INTO test VALUES(1); SELECT rowid, a FROM test; } } {1 1} do_test misc1-16.5 { execsql { INSERT INTO test VALUES(5); SELECT rowid, a FROM test; } } {1 1 5 5} do_test misc1-16.6 { execsql { INSERT INTO test VALUES(NULL); SELECT rowid, a FROM test; } } {1 1 5 5 6 6} ifcapable trigger&&tempdb { # Ticket #333: Temp triggers that modify persistent tables. # do_test misc1-17.1 { execsql { BEGIN; CREATE TABLE RealTable(TestID INTEGER PRIMARY KEY, TestString TEXT); CREATE TEMP TABLE TempTable(TestID INTEGER PRIMARY KEY, TestString TEXT); CREATE TEMP TRIGGER trigTest_1 AFTER UPDATE ON TempTable BEGIN INSERT INTO RealTable(TestString) SELECT new.TestString FROM TempTable LIMIT 1; END; INSERT INTO TempTable(TestString) VALUES ('1'); INSERT INTO TempTable(TestString) VALUES ('2'); UPDATE TempTable SET TestString = TestString + 1 WHERE TestID=1 OR TestId=2; COMMIT; SELECT TestString FROM RealTable ORDER BY 1; } } {2 3} } do_test misc1-18.1 { set n [sqlite3_sleep 100] expr {$n>=100} } {1} finish_test