1# 2009 August 06 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# 12# This file implements regression tests for SQLite library. This file 13# implements tests for range and LIKE constraints that use bound variables 14# instead of literal constant arguments. 15# 16 17set testdir [file dirname $argv0] 18source $testdir/tester.tcl 19set testprefix analyze3 20 21ifcapable !stat4 { 22 finish_test 23 return 24} 25 26#---------------------------------------------------------------------- 27# Test Organization: 28# 29# analyze3-1.*: Test that the values of bound parameters are considered 30# in the same way as constants when planning queries that 31# use range constraints. 32# 33# analyze3-2.*: Test that the values of bound parameters are considered 34# in the same way as constants when planning queries that 35# use LIKE expressions in the WHERE clause. 36# 37# analyze3-3.*: Test that binding to a variable does not invalidate the 38# query plan when there is no way in which replanning the 39# query may produce a superior outcome. 40# 41# analyze3-4.*: Test that SQL or authorization callback errors occuring 42# within sqlite3Reprepare() are handled correctly. 43# 44# analyze3-5.*: Check that the query plans of applicable statements are 45# invalidated if the values of SQL parameter are modified 46# using the clear_bindings() or transfer_bindings() APIs. 47# 48# analyze3-6.*: Test that the problem fixed by commit [127a5b776d] is fixed. 49# 50# analyze3-7.*: Test that some memory leaks discovered by fuzz testing 51# have been fixed. 52# 53 54proc getvar {varname} { uplevel #0 set $varname } 55db function var getvar 56 57proc eqp {sql {db db}} { 58 uplevel execsql [list "EXPLAIN QUERY PLAN $sql"] $db 59} 60 61proc sf_execsql {sql {db db}} { 62 set ::sqlite_search_count 0 63 set r [uplevel [list execsql $sql $db]] 64 65 concat $::sqlite_search_count [$db status step] $r 66} 67 68#------------------------------------------------------------------------- 69# 70# analyze3-1.1.1: 71# Create a table with two columns. Populate the first column (affinity 72# INTEGER) with integer values from 100 to 1100. Create an index on this 73# column. ANALYZE the table. 74# 75# analyze3-1.1.2 - 3.1.3 76# Show that there are two possible plans for querying the table with 77# a range constraint on the indexed column - "full table scan" or "use 78# the index". When the range is specified using literal values, SQLite 79# is able to pick the best plan based on the samples in sqlite_stat3. 80# 81# analyze3-1.1.4 - 3.1.9 82# Show that using SQL variables produces the same results as using 83# literal values to constrain the range scan. 84# 85# These tests also check that the compiler code considers column 86# affinities when estimating the number of rows scanned by the "use 87# index strategy". 88# 89do_test analyze3-1.1.1 { 90 execsql { 91 BEGIN; 92 CREATE TABLE t1(x INTEGER, y); 93 CREATE INDEX i1 ON t1(x); 94 } 95 for {set i 0} {$i < 1000} {incr i} { 96 execsql { INSERT INTO t1 VALUES($i+100, $i) } 97 } 98 execsql { 99 COMMIT; 100 ANALYZE; 101 } 102 103 execsql { SELECT count(*)>0 FROM sqlite_stat4; } 104} {1} 105 106do_execsql_test analyze3-1.1.x { 107 SELECT count(*) FROM t1 WHERE x>200 AND x<300; 108 SELECT count(*) FROM t1 WHERE x>0 AND x<1100; 109} {99 1000} 110 111# The first of the following two SELECT statements visits 99 rows. So 112# it is better to use the index. But the second visits every row in 113# the table (1000 in total) so it is better to do a full-table scan. 114# 115do_eqp_test analyze3-1.1.2 { 116 SELECT sum(y) FROM t1 WHERE x>200 AND x<300 117} {SEARCH TABLE t1 USING INDEX i1 (x>? AND x<?)} 118do_eqp_test analyze3-1.1.3 { 119 SELECT sum(y) FROM t1 WHERE x>0 AND x<1100 120} {SCAN TABLE t1} 121 122# 2017-06-26: Verify that the SQLITE_DBCONFIG_ENABLE_QPSG setting disables 123# the use of bound parameters by STAT4 124# 125db cache flush 126unset -nocomplain l 127unset -nocomplain u 128do_eqp_test analyze3-1.1.3.100 { 129 SELECT sum(y) FROM t1 WHERE x>$l AND x<$u 130} {SEARCH TABLE t1 USING INDEX i1 (x>? AND x<?)} 131set l 200 132set u 300 133do_eqp_test analyze3-1.1.3.101 { 134 SELECT sum(y) FROM t1 WHERE x>$l AND x<$u 135} {SEARCH TABLE t1 USING INDEX i1 (x>? AND x<?)} 136set l 0 137set u 1100 138do_eqp_test analyze3-1.1.3.102 { 139 SELECT sum(y) FROM t1 WHERE x>$l AND x<$u 140} {SCAN TABLE t1} 141db cache flush 142sqlite3_db_config db ENABLE_QPSG 1 143do_eqp_test analyze3-1.1.3.103 { 144 SELECT sum(y) FROM t1 WHERE x>$l AND x<$u 145} {SEARCH TABLE t1 USING INDEX i1 (x>? AND x<?)} 146db cache flush 147sqlite3_db_config db ENABLE_QPSG 0 148do_eqp_test analyze3-1.1.3.104 { 149 SELECT sum(y) FROM t1 WHERE x>$l AND x<$u 150} {SCAN TABLE t1} 151 152do_test analyze3-1.1.4 { 153 sf_execsql { SELECT sum(y) FROM t1 WHERE x>200 AND x<300 } 154} {199 0 14850} 155do_test analyze3-1.1.5 { 156 set l [string range "200" 0 end] 157 set u [string range "300" 0 end] 158 sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u } 159} {199 0 14850} 160do_test analyze3-1.1.6 { 161 set l [expr int(200)] 162 set u [expr int(300)] 163 sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u } 164} {199 0 14850} 165do_test analyze3-1.1.7 { 166 sf_execsql { SELECT sum(y) FROM t1 WHERE x>0 AND x<1100 } 167} {999 999 499500} 168do_test analyze3-1.1.8 { 169 set l [string range "0" 0 end] 170 set u [string range "1100" 0 end] 171 sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u } 172} {999 999 499500} 173do_test analyze3-1.1.9 { 174 set l [expr int(0)] 175 set u [expr int(1100)] 176 sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u } 177} {999 999 499500} 178 179 180# The following tests are similar to the block above. The difference is 181# that the indexed column has TEXT affinity in this case. In the tests 182# above the affinity is INTEGER. 183# 184do_test analyze3-1.2.1 { 185 execsql { 186 BEGIN; 187 CREATE TABLE t2(x TEXT, y); 188 INSERT INTO t2 SELECT * FROM t1; 189 CREATE INDEX i2 ON t2(x); 190 COMMIT; 191 ANALYZE; 192 } 193} {} 194do_execsql_test analyze3-2.1.x { 195 SELECT count(*) FROM t2 WHERE x>1 AND x<2; 196 SELECT count(*) FROM t2 WHERE x>0 AND x<99; 197} {200 990} 198do_eqp_test analyze3-1.2.2 { 199 SELECT sum(y) FROM t2 WHERE x>1 AND x<2 200} {SEARCH TABLE t2 USING INDEX i2 (x>? AND x<?)} 201do_eqp_test analyze3-1.2.3 { 202 SELECT sum(y) FROM t2 WHERE x>0 AND x<99 203} {SCAN TABLE t2} 204 205do_test analyze3-1.2.4 { 206 sf_execsql { SELECT sum(y) FROM t2 WHERE x>12 AND x<20 } 207} {161 0 4760} 208do_test analyze3-1.2.5 { 209 set l [string range "12" 0 end] 210 set u [string range "20" 0 end] 211 sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u} 212} {161 0 text text 4760} 213do_test analyze3-1.2.6 { 214 set l [expr int(12)] 215 set u [expr int(20)] 216 sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u} 217} {161 0 integer integer 4760} 218do_test analyze3-1.2.7 { 219 sf_execsql { SELECT sum(y) FROM t2 WHERE x>0 AND x<99 } 220} {999 999 490555} 221do_test analyze3-1.2.8 { 222 set l [string range "0" 0 end] 223 set u [string range "99" 0 end] 224 sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u} 225} {999 999 text text 490555} 226do_test analyze3-1.2.9 { 227 set l [expr int(0)] 228 set u [expr int(99)] 229 sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u} 230} {999 999 integer integer 490555} 231 232# Same tests a third time. This time, column x has INTEGER affinity and 233# is not the leftmost column of the table. This triggered a bug causing 234# SQLite to use sub-optimal query plans in 3.6.18 and earlier. 235# 236do_test analyze3-1.3.1 { 237 execsql { 238 BEGIN; 239 CREATE TABLE t3(y TEXT, x INTEGER); 240 INSERT INTO t3 SELECT y, x FROM t1; 241 CREATE INDEX i3 ON t3(x); 242 COMMIT; 243 ANALYZE; 244 } 245} {} 246do_execsql_test analyze3-1.3.x { 247 SELECT count(*) FROM t3 WHERE x>200 AND x<300; 248 SELECT count(*) FROM t3 WHERE x>0 AND x<1100 249} {99 1000} 250do_eqp_test analyze3-1.3.2 { 251 SELECT sum(y) FROM t3 WHERE x>200 AND x<300 252} {SEARCH TABLE t3 USING INDEX i3 (x>? AND x<?)} 253do_eqp_test analyze3-1.3.3 { 254 SELECT sum(y) FROM t3 WHERE x>0 AND x<1100 255} {SCAN TABLE t3} 256 257do_test analyze3-1.3.4 { 258 sf_execsql { SELECT sum(y) FROM t3 WHERE x>200 AND x<300 } 259} {199 0 14850} 260do_test analyze3-1.3.5 { 261 set l [string range "200" 0 end] 262 set u [string range "300" 0 end] 263 sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u } 264} {199 0 14850} 265do_test analyze3-1.3.6 { 266 set l [expr int(200)] 267 set u [expr int(300)] 268 sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u } 269} {199 0 14850} 270do_test analyze3-1.3.7 { 271 sf_execsql { SELECT sum(y) FROM t3 WHERE x>0 AND x<1100 } 272} {999 999 499500} 273do_test analyze3-1.3.8 { 274 set l [string range "0" 0 end] 275 set u [string range "1100" 0 end] 276 sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u } 277} {999 999 499500} 278do_test analyze3-1.3.9 { 279 set l [expr int(0)] 280 set u [expr int(1100)] 281 sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u } 282} {999 999 499500} 283 284#------------------------------------------------------------------------- 285# Test that the values of bound SQL variables may be used for the LIKE 286# optimization. 287# 288drop_all_tables 289do_test analyze3-2.1 { 290 execsql { 291 PRAGMA case_sensitive_like=off; 292 BEGIN; 293 CREATE TABLE t1(a, b TEXT COLLATE nocase); 294 CREATE INDEX i1 ON t1(b); 295 } 296 for {set i 0} {$i < 1000} {incr i} { 297 set t "" 298 append t [lindex {a b c d e f g h i j} [expr $i/100]] 299 append t [lindex {a b c d e f g h i j} [expr ($i/10)%10]] 300 append t [lindex {a b c d e f g h i j} [expr ($i%10)]] 301 execsql { INSERT INTO t1 VALUES($i, $t) } 302 } 303 execsql COMMIT 304} {} 305do_eqp_test analyze3-2.2 { 306 SELECT count(a) FROM t1 WHERE b LIKE 'a%' 307} {SEARCH TABLE t1 USING INDEX i1 (b>? AND b<?)} 308do_eqp_test analyze3-2.3 { 309 SELECT count(a) FROM t1 WHERE b LIKE '%a' 310} {SCAN TABLE t1} 311 312# Return the first argument if like_match_blobs is true (the default) 313# or the second argument if not 314# 315proc ilmb {a b} { 316 ifcapable like_match_blobs {return $a} 317 return $b 318} 319 320do_test analyze3-2.4 { 321 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE 'a%' } 322} [list [ilmb 102 101] 0 100] 323do_test analyze3-2.5 { 324 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE '%a' } 325} {999 999 100} 326 327do_test analyze3-2.6 { 328 set like "a%" 329 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like } 330} [list [ilmb 102 101] 0 100] 331do_test analyze3-2.7 { 332 set like "%a" 333 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like } 334} {999 999 100} 335do_test analyze3-2.8 { 336 set like "a" 337 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like } 338} [list [ilmb 102 101] 0 0] 339do_test analyze3-2.9 { 340 set like "ab" 341 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like } 342} [list [ilmb 12 11] 0 0] 343do_test analyze3-2.10 { 344 set like "abc" 345 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like } 346} [list [ilmb 3 2] 0 1] 347do_test analyze3-2.11 { 348 set like "a_c" 349 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like } 350} [list [ilmb 102 101] 0 10] 351 352 353#------------------------------------------------------------------------- 354# This block of tests checks that statements are correctly marked as 355# expired when the values bound to any parameters that may affect the 356# query plan are modified. 357# 358drop_all_tables 359db auth auth 360proc auth {args} { 361 set ::auth 1 362 return SQLITE_OK 363} 364 365do_test analyze3-3.1 { 366 execsql { 367 BEGIN; 368 CREATE TABLE t1(a, b, c); 369 CREATE INDEX i1 ON t1(b); 370 } 371 for {set i 0} {$i < 100} {incr i} { 372 execsql { INSERT INTO t1 VALUES($i, $i, $i) } 373 } 374 execsql COMMIT 375 execsql ANALYZE 376} {} 377do_test analyze3-3.2.1 { 378 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE b>?" -1 dummy] 379 sqlite3_expired $S 380} {0} 381do_test analyze3-3.2.2 { 382 sqlite3_bind_text $S 1 "abc" 3 383 sqlite3_expired $S 384} {1} 385do_test analyze3-3.2.4 { 386 sqlite3_finalize $S 387} {SQLITE_OK} 388 389do_test analyze3-3.2.5 { 390 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE b=?" -1 dummy] 391 sqlite3_expired $S 392} {0} 393do_test analyze3-3.2.6 { 394 sqlite3_bind_text $S 1 "abc" 3 395 sqlite3_expired $S 396} {1} 397do_test analyze3-3.2.7 { 398 sqlite3_finalize $S 399} {SQLITE_OK} 400 401do_test analyze3-3.4.1 { 402 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy] 403 sqlite3_expired $S 404} {0} 405do_test analyze3-3.4.2 { 406 sqlite3_bind_text $S 1 "abc" 3 407 sqlite3_expired $S 408} {0} 409do_test analyze3-3.4.3 { 410 sqlite3_bind_text $S 2 "def" 3 411 sqlite3_expired $S 412} {1} 413do_test analyze3-3.4.4 { 414 sqlite3_bind_text $S 2 "ghi" 3 415 sqlite3_expired $S 416} {1} 417do_test analyze3-3.4.5 { 418 sqlite3_expired $S 419} {1} 420do_test analyze3-3.4.6 { 421 sqlite3_finalize $S 422} {SQLITE_OK} 423 424do_test analyze3-3.5.1 { 425 set S [sqlite3_prepare_v2 db { 426 SELECT * FROM t1 WHERE a IN ( 427 ?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?10, 428 ?11, ?12, ?13, ?14, ?15, ?16, ?17, ?18, ?19, ?20, 429 ?21, ?22, ?23, ?24, ?25, ?26, ?27, ?28, ?29, ?30, ?31 430 ) AND b>?32; 431 } -1 dummy] 432 sqlite3_expired $S 433} {0} 434do_test analyze3-3.5.2 { 435 sqlite3_bind_text $S 31 "abc" 3 436 sqlite3_expired $S 437} {0} 438do_test analyze3-3.5.3 { 439 sqlite3_bind_text $S 32 "def" 3 440 sqlite3_expired $S 441} {1} 442do_test analyze3-3.5.5 { 443 sqlite3_finalize $S 444} {SQLITE_OK} 445 446do_test analyze3-3.6.1 { 447 set S [sqlite3_prepare_v2 db { 448 SELECT * FROM t1 WHERE a IN ( 449 ?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?10, 450 ?11, ?12, ?13, ?14, ?15, ?16, ?17, ?18, ?19, ?20, 451 ?21, ?22, ?23, ?24, ?25, ?26, ?27, ?28, ?29, ?30, ?31, ?32 452 ) AND b>?33; 453 } -1 dummy] 454 sqlite3_expired $S 455} {0} 456do_test analyze3-3.6.2 { 457 sqlite3_bind_text $S 32 "abc" 3 458 sqlite3_expired $S 459} {1} 460do_test analyze3-3.6.3 { 461 sqlite3_bind_text $S 33 "def" 3 462 sqlite3_expired $S 463} {1} 464do_test analyze3-3.6.5 { 465 sqlite3_finalize $S 466} {SQLITE_OK} 467 468do_test analyze3-3.7.1 { 469 set S [sqlite3_prepare_v2 db { 470 SELECT * FROM t1 WHERE a IN ( 471 ?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?33, 472 ?11, ?12, ?13, ?14, ?15, ?16, ?17, ?18, ?19, ?20, 473 ?21, ?22, ?23, ?24, ?25, ?26, ?27, ?28, ?29, ?30, ?31, ?32 474 ) AND b>?10; 475 } -1 dummy] 476 sqlite3_expired $S 477} {0} 478do_test analyze3-3.7.2 { 479 sqlite3_bind_text $S 32 "abc" 3 480 sqlite3_expired $S 481} {0} 482do_test analyze3-3.7.3 { 483 sqlite3_bind_text $S 33 "def" 3 484 sqlite3_expired $S 485} {0} 486do_test analyze3-3.7.4 { 487 sqlite3_bind_text $S 10 "def" 3 488 sqlite3_expired $S 489} {1} 490do_test analyze3-3.7.6 { 491 sqlite3_finalize $S 492} {SQLITE_OK} 493 494do_test analyze3-3.8.1 { 495 execsql { 496 CREATE TABLE t4(x, y TEXT COLLATE NOCASE); 497 CREATE INDEX i4 ON t4(y); 498 } 499} {} 500do_test analyze3-3.8.2 { 501 set S [sqlite3_prepare_v2 db { 502 SELECT * FROM t4 WHERE x != ? AND y LIKE ? 503 } -1 dummy] 504 sqlite3_expired $S 505} {0} 506do_test analyze3-3.8.3 { 507 sqlite3_bind_text $S 1 "abc" 3 508 sqlite3_expired $S 509} {0} 510do_test analyze3-3.8.4 { 511 sqlite3_bind_text $S 2 "def" 3 512 sqlite3_expired $S 513} {1} 514do_test analyze3-3.8.7 { 515 sqlite3_bind_text $S 2 "ghi%" 4 516 sqlite3_expired $S 517} {1} 518do_test analyze3-3.8.8 { 519 sqlite3_expired $S 520} {1} 521do_test analyze3-3.8.9 { 522 sqlite3_bind_text $S 2 "ghi%def" 7 523 sqlite3_expired $S 524} {1} 525do_test analyze3-3.8.10 { 526 sqlite3_expired $S 527} {1} 528do_test analyze3-3.8.11 { 529 sqlite3_bind_text $S 2 "%ab" 3 530 sqlite3_expired $S 531} {1} 532do_test analyze3-3.8.12 { 533 sqlite3_expired $S 534} {1} 535do_test analyze3-3.8.12 { 536 sqlite3_bind_text $S 2 "%de" 3 537 sqlite3_expired $S 538} {1} 539do_test analyze3-3.8.13 { 540 sqlite3_expired $S 541} {1} 542do_test analyze3-3.8.14 { 543 sqlite3_finalize $S 544} {SQLITE_OK} 545 546#------------------------------------------------------------------------- 547# These tests check that errors encountered while repreparing an SQL 548# statement within sqlite3Reprepare() are handled correctly. 549# 550 551# Check a schema error. 552# 553do_test analyze3-4.1.1 { 554 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy] 555 sqlite3_step $S 556} {SQLITE_DONE} 557do_test analyze3-4.1.2 { 558 sqlite3_reset $S 559 sqlite3_bind_text $S 2 "abc" 3 560 execsql { DROP TABLE t1 } 561 sqlite3_step $S 562} {SQLITE_ERROR} 563do_test analyze3-4.1.3 { 564 sqlite3_finalize $S 565} {SQLITE_ERROR} 566 567# Check an authorization error. 568# 569do_test analyze3-4.2.1 { 570 execsql { 571 BEGIN; 572 CREATE TABLE t1(a, b, c); 573 CREATE INDEX i1 ON t1(b); 574 } 575 for {set i 0} {$i < 100} {incr i} { 576 execsql { INSERT INTO t1 VALUES($i, $i, $i) } 577 } 578 execsql COMMIT 579 execsql ANALYZE 580 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy] 581 sqlite3_step $S 582} {SQLITE_DONE} 583db auth auth 584proc auth {args} { 585 if {[lindex $args 0] == "SQLITE_READ"} {return SQLITE_DENY} 586 return SQLITE_OK 587} 588do_test analyze3-4.2.2 { 589 sqlite3_reset $S 590 sqlite3_bind_text $S 2 "abc" 3 591 sqlite3_step $S 592} {SQLITE_AUTH} 593do_test analyze3-4.2.4 { 594 sqlite3_finalize $S 595} {SQLITE_AUTH} 596 597# Check the effect of an authorization error that occurs in a re-prepare 598# performed by sqlite3_step() is the same as one that occurs within 599# sqlite3Reprepare(). 600# 601do_test analyze3-4.3.1 { 602 db auth {} 603 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy] 604 execsql { CREATE TABLE t2(d, e, f) } 605 db auth auth 606 sqlite3_step $S 607} {SQLITE_AUTH} 608do_test analyze3-4.3.2 { 609 sqlite3_finalize $S 610} {SQLITE_AUTH} 611db auth {} 612 613#------------------------------------------------------------------------- 614# Test that modifying bound variables using the clear_bindings() or 615# transfer_bindings() APIs works. 616# 617# analyze3-5.1.*: sqlite3_clear_bindings() 618# analyze3-5.2.*: sqlite3_transfer_bindings() 619# 620do_test analyze3-5.1.1 { 621 drop_all_tables 622 execsql { 623 CREATE TABLE t1(x TEXT COLLATE NOCASE); 624 CREATE INDEX i1 ON t1(x); 625 INSERT INTO t1 VALUES('aaa'); 626 INSERT INTO t1 VALUES('abb'); 627 INSERT INTO t1 VALUES('acc'); 628 INSERT INTO t1 VALUES('baa'); 629 INSERT INTO t1 VALUES('bbb'); 630 INSERT INTO t1 VALUES('bcc'); 631 } 632 633 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE x LIKE ?" -1 dummy] 634 sqlite3_bind_text $S 1 "a%" 2 635 set R [list] 636 while { "SQLITE_ROW" == [sqlite3_step $S] } { 637 lappend R [sqlite3_column_text $S 0] 638 } 639 concat [sqlite3_reset $S] $R 640} {SQLITE_OK aaa abb acc} 641do_test analyze3-5.1.2 { 642 sqlite3_clear_bindings $S 643 set R [list] 644 while { "SQLITE_ROW" == [sqlite3_step $S] } { 645 lappend R [sqlite3_column_text $S 0] 646 } 647 concat [sqlite3_reset $S] $R 648} {SQLITE_OK} 649do_test analyze3-5.1.3 { 650 sqlite3_finalize $S 651} {SQLITE_OK} 652 653do_test analyze3-5.1.1 { 654 set S1 [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE x LIKE ?" -1 dummy] 655 sqlite3_bind_text $S1 1 "b%" 2 656 set R [list] 657 while { "SQLITE_ROW" == [sqlite3_step $S1] } { 658 lappend R [sqlite3_column_text $S1 0] 659 } 660 concat [sqlite3_reset $S1] $R 661} {SQLITE_OK baa bbb bcc} 662 663do_test analyze3-5.1.2 { 664 set S2 [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE x = ?" -1 dummy] 665 sqlite3_bind_text $S2 1 "a%" 2 666 sqlite3_transfer_bindings $S2 $S1 667 set R [list] 668 while { "SQLITE_ROW" == [sqlite3_step $S1] } { 669 lappend R [sqlite3_column_text $S1 0] 670 } 671 concat [sqlite3_reset $S1] $R 672} {SQLITE_OK aaa abb acc} 673do_test analyze3-5.1.3 { 674 sqlite3_finalize $S2 675 sqlite3_finalize $S1 676} {SQLITE_OK} 677 678#------------------------------------------------------------------------- 679 680do_test analyze3-6.1 { 681 execsql { DROP TABLE IF EXISTS t1 } 682 execsql BEGIN 683 execsql { CREATE TABLE t1(a, b, c) } 684 for {set i 0} {$i < 1000} {incr i} { 685 execsql "INSERT INTO t1 VALUES([expr $i/100], 'x', [expr $i/10])" 686 } 687 execsql { 688 CREATE INDEX i1 ON t1(a, b); 689 CREATE INDEX i2 ON t1(c); 690 } 691 execsql COMMIT 692 execsql ANALYZE 693} {} 694 695do_eqp_test analyze3-6-3 { 696 SELECT * FROM t1 WHERE a = 5 AND c = 13; 697} {SEARCH TABLE t1 USING INDEX i2 (c=?)} 698 699do_eqp_test analyze3-6-2 { 700 SELECT * FROM t1 WHERE a = 5 AND b > 'w' AND c = 13; 701} {SEARCH TABLE t1 USING INDEX i2 (c=?)} 702 703#----------------------------------------------------------------------------- 704# 2015-04-20. 705# Memory leak in sqlite3Stat4ProbeFree(). (Discovered while fuzzing.) 706# 707do_execsql_test analyze-7.1 { 708 DROP TABLE IF EXISTS t1; 709 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c); 710 INSERT INTO t1 VALUES(1,1,'0000'); 711 CREATE INDEX t0b ON t1(b); 712 ANALYZE; 713 SELECT c FROM t1 WHERE b=3 AND a BETWEEN 30 AND hex(1); 714} {} 715 716# At one point duplicate stat1 entries were causing a memory leak. 717# 718reset_db 719do_execsql_test 7.2 { 720 CREATE TABLE t1(a,b,c); 721 CREATE INDEX t1a ON t1(a); 722 ANALYZE; 723 SELECT * FROM sqlite_stat1; 724 INSERT INTO sqlite_stat1(tbl,idx,stat) VALUES('t1','t1a','12000'); 725 INSERT INTO sqlite_stat1(tbl,idx,stat) VALUES('t1','t1a','12000'); 726 ANALYZE sqlite_master; 727} 728 729finish_test 730