1# 2001 September 15 2# 3# The author disclaims copyright to this source code. In place of 4# a legal notice, here is a blessing: 5# 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. 9# 10#*********************************************************************** 11# This file implements regression tests for SQLite library. 12# 13# This file implements tests for miscellanous features that were 14# left out of other test files. 15# 16# $Id: misc1.test,v 1.23 2003/08/05 13:13:39 drh Exp $ 17 18set testdir [file dirname $argv0] 19source $testdir/tester.tcl 20 21# Test the creation and use of tables that have a large number 22# of columns. 23# 24do_test misc1-1.1 { 25 set cmd "CREATE TABLE manycol(x0 text" 26 for {set i 1} {$i<=99} {incr i} { 27 append cmd ",x$i text" 28 } 29 append cmd ")"; 30 execsql $cmd 31 set cmd "INSERT INTO manycol VALUES(0" 32 for {set i 1} {$i<=99} {incr i} { 33 append cmd ",$i" 34 } 35 append cmd ")"; 36 execsql $cmd 37 execsql "SELECT x99 FROM manycol" 38} 99 39do_test misc1-1.2 { 40 execsql {SELECT x0, x10, x25, x50, x75 FROM manycol} 41} {0 10 25 50 75} 42do_test misc1-1.3.1 { 43 for {set j 100} {$j<=1000} {incr j 100} { 44 set cmd "INSERT INTO manycol VALUES($j" 45 for {set i 1} {$i<=99} {incr i} { 46 append cmd ",[expr {$i+$j}]" 47 } 48 append cmd ")" 49 execsql $cmd 50 } 51 execsql {SELECT x50 FROM manycol ORDER BY x80+0} 52} {50 150 250 350 450 550 650 750 850 950 1050} 53do_test misc1-1.3.2 { 54 execsql {SELECT x50 FROM manycol ORDER BY x80} 55} {1050 150 250 350 450 550 650 750 50 850 950} 56do_test misc1-1.4 { 57 execsql {SELECT x75 FROM manycol WHERE x50=350} 58} 375 59do_test misc1-1.5 { 60 execsql {SELECT x50 FROM manycol WHERE x99=599} 61} 550 62do_test misc1-1.6 { 63 execsql {CREATE INDEX manycol_idx1 ON manycol(x99)} 64 execsql {SELECT x50 FROM manycol WHERE x99=899} 65} 850 66do_test misc1-1.7 { 67 execsql {SELECT count(*) FROM manycol} 68} 11 69do_test misc1-1.8 { 70 execsql {DELETE FROM manycol WHERE x98=1234} 71 execsql {SELECT count(*) FROM manycol} 72} 11 73do_test misc1-1.9 { 74 execsql {DELETE FROM manycol WHERE x98=998} 75 execsql {SELECT count(*) FROM manycol} 76} 10 77do_test misc1-1.10 { 78 execsql {DELETE FROM manycol WHERE x99=500} 79 execsql {SELECT count(*) FROM manycol} 80} 10 81do_test misc1-1.11 { 82 execsql {DELETE FROM manycol WHERE x99=599} 83 execsql {SELECT count(*) FROM manycol} 84} 9 85 86# Check GROUP BY expressions that name two or more columns. 87# 88do_test misc1-2.1 { 89 execsql { 90 BEGIN TRANSACTION; 91 CREATE TABLE agger(one text, two text, three text, four text); 92 INSERT INTO agger VALUES(1, 'one', 'hello', 'yes'); 93 INSERT INTO agger VALUES(2, 'two', 'howdy', 'no'); 94 INSERT INTO agger VALUES(3, 'thr', 'howareya', 'yes'); 95 INSERT INTO agger VALUES(4, 'two', 'lothere', 'yes'); 96 INSERT INTO agger VALUES(5, 'one', 'atcha', 'yes'); 97 INSERT INTO agger VALUES(6, 'two', 'hello', 'no'); 98 COMMIT 99 } 100 execsql {SELECT count(*) FROM agger} 101} 6 102do_test misc1-2.2 { 103 execsql {SELECT sum(one), two, four FROM agger 104 GROUP BY two, four ORDER BY sum(one) desc} 105} {8 two no 6 one yes 4 two yes 3 thr yes} 106do_test misc1-2.3 { 107 execsql {SELECT sum((one)), (two), (four) FROM agger 108 GROUP BY (two), (four) ORDER BY sum(one) desc} 109} {8 two no 6 one yes 4 two yes 3 thr yes} 110 111# Here's a test for a bug found by Joel Lucsy. The code below 112# was causing an assertion failure. 113# 114do_test misc1-3.1 { 115 set r [execsql { 116 CREATE TABLE t1(a); 117 INSERT INTO t1 VALUES('hi'); 118 PRAGMA full_column_names=on; 119 SELECT rowid, * FROM t1; 120 }] 121 lindex $r 1 122} {hi} 123 124# Here's a test for yet another bug found by Joel Lucsy. The code 125# below was causing an assertion failure. 126# 127do_test misc1-4.1 { 128 execsql { 129 BEGIN; 130 CREATE TABLE t2(a); 131 INSERT INTO t2 VALUES('This is a long string to use up a lot of disk -'); 132 UPDATE t2 SET a=a||a||a||a; 133 INSERT INTO t2 SELECT '1 - ' || a FROM t2; 134 INSERT INTO t2 SELECT '2 - ' || a FROM t2; 135 INSERT INTO t2 SELECT '3 - ' || a FROM t2; 136 INSERT INTO t2 SELECT '4 - ' || a FROM t2; 137 INSERT INTO t2 SELECT '5 - ' || a FROM t2; 138 INSERT INTO t2 SELECT '6 - ' || a FROM t2; 139 COMMIT; 140 SELECT count(*) FROM t2; 141 } 142} {64} 143 144# Make sure we actually see a semicolon or end-of-file in the SQL input 145# before executing a command. Thus if "WHERE" is misspelled on an UPDATE, 146# the user won't accidently update every record. 147# 148do_test misc1-5.1 { 149 catchsql { 150 CREATE TABLE t3(a,b); 151 INSERT INTO t3 VALUES(1,2); 152 INSERT INTO t3 VALUES(3,4); 153 UPDATE t3 SET a=0 WHEREwww b=2; 154 } 155} {1 {near "WHEREwww": syntax error}} 156do_test misc1-5.2 { 157 execsql { 158 SELECT * FROM t3 ORDER BY a; 159 } 160} {1 2 3 4} 161 162# Certain keywords (especially non-standard keywords like "REPLACE") can 163# also be used as identifiers. The way this works in the parser is that 164# the parser first detects a syntax error, the error handling routine 165# sees that the special keyword caused the error, then replaces the keyword 166# with "ID" and tries again. 167# 168# Check the operation of this logic. 169# 170do_test misc1-6.1 { 171 catchsql { 172 CREATE TABLE t4( 173 abort, asc, begin, cluster, conflict, copy, delimiters, desc, end, 174 explain, fail, ignore, key, offset, pragma, replace, temp, 175 vacuum, view 176 ); 177 } 178} {0 {}} 179do_test misc1-6.2 { 180 catchsql { 181 INSERT INTO t4 182 VALUES(1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19); 183 } 184} {0 {}} 185do_test misc1-6.3 { 186 execsql { 187 SELECT * FROM t4 188 } 189} {1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19} 190do_test misc1-6.4 { 191 execsql { 192 SELECT abort+asc,max(key,pragma,temp) FROM t4 193 } 194} {3 17} 195 196# Test for multi-column primary keys, and for multiple primary keys. 197# 198do_test misc1-7.1 { 199 catchsql { 200 CREATE TABLE error1( 201 a TYPE PRIMARY KEY, 202 b TYPE PRIMARY KEY 203 ); 204 } 205} {1 {table "error1" has more than one primary key}} 206do_test misc1-7.2 { 207 catchsql { 208 CREATE TABLE error1( 209 a INTEGER PRIMARY KEY, 210 b TYPE PRIMARY KEY 211 ); 212 } 213} {1 {table "error1" has more than one primary key}} 214do_test misc1-7.3 { 215 execsql { 216 CREATE TABLE t5(a,b,c,PRIMARY KEY(a,b)); 217 INSERT INTO t5 VALUES(1,2,3); 218 SELECT * FROM t5 ORDER BY a; 219 } 220} {1 2 3} 221do_test misc1-7.4 { 222 catchsql { 223 INSERT INTO t5 VALUES(1,2,4); 224 } 225} {1 {columns a, b are not unique}} 226do_test misc1-7.5 { 227 catchsql { 228 INSERT INTO t5 VALUES(0,2,4); 229 } 230} {0 {}} 231do_test misc1-7.6 { 232 execsql { 233 SELECT * FROM t5 ORDER BY a; 234 } 235} {0 2 4 1 2 3} 236 237do_test misc1-8.1 { 238 catchsql { 239 SELECT *; 240 } 241} {1 {no tables specified}} 242do_test misc1-8.2 { 243 catchsql { 244 SELECT t1.*; 245 } 246} {1 {no such table: t1}} 247 248execsql { 249 DROP TABLE t1; 250 DROP TABLE t2; 251 DROP TABLE t3; 252 DROP TABLE t4; 253} 254 255# If an integer is too big to be represented as a 32-bit machine integer, 256# then treat it as a string. 257# 258do_test misc1-9.1 { 259 catchsql { 260 CREATE TABLE t1(a unique not null, b unique not null); 261 INSERT INTO t1 VALUES('a',12345678901234567890); 262 INSERT INTO t1 VALUES('b',12345678911234567890); 263 INSERT INTO t1 VALUES('c',12345678921234567890); 264 SELECT * FROM t1; 265 } 266} {0 {a 12345678901234567890 b 12345678911234567890 c 12345678921234567890}} 267 268# A WHERE clause is not allowed to contain more than 99 terms. Check to 269# make sure this limit is enforced. 270# 271do_test misc1-10.0 { 272 execsql {SELECT count(*) FROM manycol} 273} {9} 274do_test misc1-10.1 { 275 set ::where {WHERE x0>=0} 276 for {set i 1} {$i<=99} {incr i} { 277 append ::where " AND x$i<>0" 278 } 279 catchsql "SELECT count(*) FROM manycol $::where" 280} {0 9} 281do_test misc1-10.2 { 282 catchsql "SELECT count(*) FROM manycol $::where AND rowid>0" 283} {1 {WHERE clause too complex - no more than 100 terms allowed}} 284do_test misc1-10.3 { 285 regsub "x0>=0" $::where "x0=0" ::where 286 catchsql "DELETE FROM manycol $::where" 287} {0 {}} 288do_test misc1-10.4 { 289 execsql {SELECT count(*) FROM manycol} 290} {8} 291do_test misc1-10.5 { 292 catchsql "DELETE FROM manycol $::where AND rowid>0" 293} {1 {WHERE clause too complex - no more than 100 terms allowed}} 294do_test misc1-10.6 { 295 execsql {SELECT x1 FROM manycol WHERE x0=100} 296} {101} 297do_test misc1-10.7 { 298 regsub "x0=0" $::where "x0=100" ::where 299 catchsql "UPDATE manycol SET x1=x1+1 $::where" 300} {0 {}} 301do_test misc1-10.8 { 302 execsql {SELECT x1 FROM manycol WHERE x0=100} 303} {102} 304do_test misc1-10.9 { 305 catchsql "UPDATE manycol SET x1=x1+1 $::where AND rowid>0" 306} {1 {WHERE clause too complex - no more than 100 terms allowed}} 307do_test misc1-10.10 { 308 execsql {SELECT x1 FROM manycol WHERE x0=100} 309} {102} 310 311# Make sure the initialization works even if a database is opened while 312# another process has the database locked. 313# 314do_test misc1-11.1 { 315 execsql {BEGIN} 316 sqlite db2 test.db 317 set rc [catch {db2 eval {SELECT count(*) FROM t1}} msg] 318 lappend rc $msg 319} {1 {database is locked}} 320do_test misc1-11.2 { 321 execsql {COMMIT} 322 set rc [catch {db2 eval {SELECT count(*) FROM t1}} msg] 323 db2 close 324 lappend rc $msg 325} {0 3} 326 327# Make sure string comparisons really do compare strings in format4+. 328# Similar tests in the format3.test file show that for format3 and earlier 329# all comparisions where numeric if either operand looked like a number. 330# 331do_test misc1-12.1 { 332 execsql {SELECT '0'=='0.0'} 333} {0} 334do_test misc1-12.2 { 335 execsql {SELECT '0'==0.0} 336} {1} 337do_test misc1-12.3 { 338 execsql {SELECT '12345678901234567890'=='12345678901234567891'} 339} {0} 340do_test misc1-12.4 { 341 execsql { 342 CREATE TABLE t6(a INT UNIQUE, b TEXT UNIQUE); 343 INSERT INTO t6 VALUES('0','0.0'); 344 SELECT * FROM t6; 345 } 346} {0 0.0} 347do_test misc1-12.5 { 348 execsql { 349 INSERT OR IGNORE INTO t6 VALUES(0.0,'x'); 350 SELECT * FROM t6; 351 } 352} {0 0.0} 353do_test misc1-12.6 { 354 execsql { 355 INSERT OR IGNORE INTO t6 VALUES('y',0); 356 SELECT * FROM t6; 357 } 358} {0 0.0 y 0} 359do_test misc1-12.7 { 360 execsql { 361 CREATE TABLE t7(x INTEGER, y TEXT, z); 362 INSERT INTO t7 VALUES(0,0,1); 363 INSERT INTO t7 VALUES(0.0,0,2); 364 INSERT INTO t7 VALUES(0,0.0,3); 365 INSERT INTO t7 VALUES(0.0,0.0,4); 366 SELECT DISTINCT x, y FROM t7 ORDER BY z; 367 } 368} {0 0 0 0.0} 369do_test misc1-12.8 { 370 execsql { 371 SELECT min(z), max(z), count(z) FROM t7 GROUP BY x ORDER BY 1; 372 } 373} {1 4 4} 374do_test misc1-12.9 { 375 execsql { 376 SELECT min(z), max(z), count(z) FROM t7 GROUP BY y ORDER BY 1; 377 } 378} {1 2 2 3 4 2} 379 380# This used to be an error. But we changed the code so that arbitrary 381# identifiers can be used as a collating sequence. Collation is by text 382# if the identifier contains "text", "blob", or "clob" and is numeric 383# otherwise. 384do_test misc1-12.10 { 385 catchsql { 386 SELECT * FROM t6 ORDER BY a COLLATE unknown; 387 } 388} {0 {0 0.0 y 0}} 389do_test misc1-12.11 { 390 execsql { 391 CREATE TABLE t8(x TEXT COLLATE numeric, y INTEGER COLLATE text, z); 392 INSERT INTO t8 VALUES(0,0,1); 393 INSERT INTO t8 VALUES(0.0,0,2); 394 INSERT INTO t8 VALUES(0,0.0,3); 395 INSERT INTO t8 VALUES(0.0,0.0,4); 396 SELECT DISTINCT x, y FROM t8 ORDER BY z; 397 } 398} {0 0 0 0.0} 399do_test misc1-12.12 { 400 execsql { 401 SELECT min(z), max(z), count(z) FROM t8 GROUP BY x ORDER BY 1; 402 } 403} {1 4 4} 404do_test misc1-12.13 { 405 execsql { 406 SELECT min(z), max(z), count(z) FROM t8 GROUP BY y ORDER BY 1; 407 } 408} {1 2 2 3 4 2} 409 410# There was a problem with realloc() in the OP_MemStore operation of 411# the VDBE. A buffer was being reallocated but some pointers into 412# the old copy of the buffer were not being moved over to the new copy. 413# The following code tests for the problem. 414# 415do_test misc1-13.1 { 416 execsql { 417 CREATE TABLE t9(x,y); 418 INSERT INTO t9 VALUES('one',1); 419 INSERT INTO t9 VALUES('two',2); 420 INSERT INTO t9 VALUES('three',3); 421 INSERT INTO t9 VALUES('four',4); 422 INSERT INTO t9 VALUES('five',5); 423 INSERT INTO t9 VALUES('six',6); 424 INSERT INTO t9 VALUES('seven',7); 425 INSERT INTO t9 VALUES('eight',8); 426 INSERT INTO t9 VALUES('nine',9); 427 INSERT INTO t9 VALUES('ten',10); 428 INSERT INTO t9 VALUES('eleven',11); 429 SELECT y FROM t9 430 WHERE x=(SELECT x FROM t9 WHERE y=1) 431 OR x=(SELECT x FROM t9 WHERE y=2) 432 OR x=(SELECT x FROM t9 WHERE y=3) 433 OR x=(SELECT x FROM t9 WHERE y=4) 434 OR x=(SELECT x FROM t9 WHERE y=5) 435 OR x=(SELECT x FROM t9 WHERE y=6) 436 OR x=(SELECT x FROM t9 WHERE y=7) 437 OR x=(SELECT x FROM t9 WHERE y=8) 438 OR x=(SELECT x FROM t9 WHERE y=9) 439 OR x=(SELECT x FROM t9 WHERE y=10) 440 OR x=(SELECT x FROM t9 WHERE y=11) 441 OR x=(SELECT x FROM t9 WHERE y=12) 442 OR x=(SELECT x FROM t9 WHERE y=13) 443 OR x=(SELECT x FROM t9 WHERE y=14) 444 ; 445 } 446} {1 2 3 4 5 6 7 8 9 10 11} 447 448# Make sure a database connection still works after changing the 449# working directory. 450# 451do_test misc1-14.1 { 452 file mkdir tempdir 453 cd tempdir 454 execsql {BEGIN} 455 file exists ./test.db-journal 456} {0} 457do_test misc1-14.2 { 458 file exists ../test.db-journal 459} {1} 460do_test misc1-14.3 { 461 cd .. 462 file delete tempdir 463 execsql {COMMIT} 464 file exists ./test.db-journal 465} {0} 466 467# A failed create table should not leave the table in the internal 468# data structures. Ticket #238. 469# 470do_test misc1-15.1 { 471 catchsql { 472 CREATE TABLE t10 AS SELECT c1; 473 } 474} {1 {no such column: c1}} 475do_test misc1-15.2 { 476 catchsql { 477 CREATE TABLE t10 AS SELECT 1; 478 } 479 # The bug in ticket #238 causes the statement above to fail with 480 # the error "table t10 alread exists" 481} {0 {}} 482 483# Test for memory leaks when a CREATE TABLE containing a primary key 484# fails. Ticket #249. 485# 486do_test misc1-16.1 { 487 catchsql {SELECT name FROM sqlite_master LIMIT 1} 488 catchsql { 489 CREATE TABLE test(a integer, primary key(a)); 490 } 491} {0 {}} 492do_test misc1-16.2 { 493 catchsql { 494 CREATE TABLE test(a integer, primary key(a)); 495 } 496} {1 {table test already exists}} 497do_test misc1-16.3 { 498 catchsql { 499 CREATE TABLE test2(a text primary key, b text, primary key(a,b)); 500 } 501} {1 {table "test2" has more than one primary key}} 502do_test misc1-16.4 { 503 execsql { 504 INSERT INTO test VALUES(1); 505 SELECT rowid, a FROM test; 506 } 507} {1 1} 508do_test misc1-16.5 { 509 execsql { 510 INSERT INTO test VALUES(5); 511 SELECT rowid, a FROM test; 512 } 513} {1 1 5 5} 514do_test misc1-16.6 { 515 execsql { 516 INSERT INTO test VALUES(NULL); 517 SELECT rowid, a FROM test; 518 } 519} {1 1 5 5 6 6} 520 521# Ticket #333: Temp triggers that modify persistent tables. 522# 523do_test misc1-17.1 { 524 execsql { 525 BEGIN; 526 CREATE TABLE RealTable(TestID INTEGER PRIMARY KEY, TestString TEXT); 527 CREATE TEMP TABLE TempTable(TestID INTEGER PRIMARY KEY, TestString TEXT); 528 CREATE TEMP TRIGGER trigTest_1 AFTER UPDATE ON TempTable BEGIN 529 INSERT INTO RealTable(TestString) 530 SELECT new.TestString FROM TempTable LIMIT 1; 531 END; 532 INSERT INTO TempTable(TestString) VALUES ('1'); 533 INSERT INTO TempTable(TestString) VALUES ('2'); 534 UPDATE TempTable SET TestString = TestString + 1 WHERE TestID IN (1, 2); 535 COMMIT; 536 SELECT TestString FROM RealTable ORDER BY 1; 537 } 538} {2 3} 539 540finish_test 541