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