where2.test 21 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719
  1. # 2005 July 28
  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. The
  12. # focus of this file is testing the use of indices in WHERE clauses
  13. # based on recent changes to the optimizer.
  14. #
  15. # $Id: where2.test,v 1.15 2009/02/02 01:50:40 drh Exp $
  16. set testdir [file dirname $argv0]
  17. source $testdir/tester.tcl
  18. # Build some test data
  19. #
  20. do_test where2-1.0 {
  21. execsql {
  22. BEGIN;
  23. CREATE TABLE t1(w int, x int, y int, z int);
  24. }
  25. for {set i 1} {$i<=100} {incr i} {
  26. set w $i
  27. set x [expr {int(log($i)/log(2))}]
  28. set y [expr {$i*$i + 2*$i + 1}]
  29. set z [expr {$x+$y}]
  30. ifcapable tclvar {
  31. execsql {INSERT INTO t1 VALUES($::w,$::x,$::y,$::z)}
  32. } else {
  33. execsql {INSERT INTO t1 VALUES(:w,:x,:y,:z)}
  34. }
  35. }
  36. execsql {
  37. CREATE UNIQUE INDEX i1w ON t1(w);
  38. CREATE INDEX i1xy ON t1(x,y);
  39. CREATE INDEX i1zyx ON t1(z,y,x);
  40. COMMIT;
  41. }
  42. } {}
  43. # Do an SQL statement. Append the search count to the end of the result.
  44. #
  45. proc count sql {
  46. set ::sqlite_search_count 0
  47. return [concat [execsql $sql] $::sqlite_search_count]
  48. }
  49. # This procedure executes the SQL. Then it checks to see if the OP_Sort
  50. # opcode was executed. If an OP_Sort did occur, then "sort" is appended
  51. # to the result. If no OP_Sort happened, then "nosort" is appended.
  52. #
  53. # This procedure is used to check to make sure sorting is or is not
  54. # occurring as expected.
  55. #
  56. proc cksort {sql} {
  57. set data [execsql $sql]
  58. if {[db status sort]} {set x sort} {set x nosort}
  59. lappend data $x
  60. return $data
  61. }
  62. # This procedure executes the SQL. Then it appends to the result the
  63. # "sort" or "nosort" keyword (as in the cksort procedure above) then
  64. # it appends the name of the table and index used.
  65. #
  66. proc queryplan {sql} {
  67. set ::sqlite_sort_count 0
  68. set data [execsql $sql]
  69. if {$::sqlite_sort_count} {set x sort} {set x nosort}
  70. lappend data $x
  71. set eqp [execsql "EXPLAIN QUERY PLAN $sql"]
  72. # puts eqp=$eqp
  73. foreach {a b c x} $eqp {
  74. if {[regexp { TABLE (\w+ AS )?(\w+) USING.* INDEX (\w+)\y} \
  75. $x all as tab idx]} {
  76. lappend data $tab $idx
  77. } elseif {[regexp { TABLE (\w+ AS )?(\w+)\y} $x all as tab]} {
  78. lappend data $tab *
  79. }
  80. }
  81. return $data
  82. }
  83. # Prefer a UNIQUE index over another index.
  84. #
  85. do_test where2-1.1 {
  86. queryplan {
  87. SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396
  88. }
  89. } {85 6 7396 7402 nosort t1 i1w}
  90. # Always prefer a rowid== constraint over any other index.
  91. #
  92. do_test where2-1.3 {
  93. queryplan {
  94. SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396 AND rowid=85
  95. }
  96. } {85 6 7396 7402 nosort t1 *}
  97. # When constrained by a UNIQUE index, the ORDER BY clause is always ignored.
  98. #
  99. do_test where2-2.1 {
  100. queryplan {
  101. SELECT * FROM t1 WHERE w=85 ORDER BY random();
  102. }
  103. } {85 6 7396 7402 nosort t1 i1w}
  104. do_test where2-2.2 {
  105. queryplan {
  106. SELECT * FROM t1 WHERE x=6 AND y=7396 ORDER BY random();
  107. }
  108. } {85 6 7396 7402 sort t1 i1xy}
  109. do_test where2-2.3 {
  110. queryplan {
  111. SELECT * FROM t1 WHERE rowid=85 AND x=6 AND y=7396 ORDER BY random();
  112. }
  113. } {85 6 7396 7402 nosort t1 *}
  114. # Efficient handling of forward and reverse table scans.
  115. #
  116. do_test where2-3.1 {
  117. queryplan {
  118. SELECT * FROM t1 ORDER BY rowid LIMIT 2
  119. }
  120. } {1 0 4 4 2 1 9 10 nosort t1 *}
  121. do_test where2-3.2 {
  122. queryplan {
  123. SELECT * FROM t1 ORDER BY rowid DESC LIMIT 2
  124. }
  125. } {100 6 10201 10207 99 6 10000 10006 nosort t1 *}
  126. # The IN operator can be used by indices at multiple layers
  127. #
  128. ifcapable subquery {
  129. do_test where2-4.1 {
  130. queryplan {
  131. SELECT * FROM t1 WHERE z IN (10207,10006) AND y IN (10000,10201)
  132. AND x>0 AND x<10
  133. ORDER BY w
  134. }
  135. } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
  136. do_test where2-4.2 {
  137. queryplan {
  138. SELECT * FROM t1 WHERE z IN (10207,10006) AND y=10000
  139. AND x>0 AND x<10
  140. ORDER BY w
  141. }
  142. } {99 6 10000 10006 sort t1 i1zyx}
  143. do_test where2-4.3 {
  144. queryplan {
  145. SELECT * FROM t1 WHERE z=10006 AND y IN (10000,10201)
  146. AND x>0 AND x<10
  147. ORDER BY w
  148. }
  149. } {99 6 10000 10006 sort t1 i1zyx}
  150. ifcapable compound {
  151. do_test where2-4.4 {
  152. queryplan {
  153. SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
  154. AND y IN (10000,10201)
  155. AND x>0 AND x<10
  156. ORDER BY w
  157. }
  158. } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
  159. do_test where2-4.5 {
  160. queryplan {
  161. SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
  162. AND y IN (SELECT 10000 UNION SELECT 10201)
  163. AND x>0 AND x<10
  164. ORDER BY w
  165. }
  166. } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
  167. }
  168. do_test where2-4.6a {
  169. queryplan {
  170. SELECT * FROM t1
  171. WHERE x IN (1,2,3,4,5,6,7,8)
  172. AND y IN (10000,10001,10002,10003,10004,10005)
  173. ORDER BY x
  174. }
  175. } {99 6 10000 10006 nosort t1 i1xy}
  176. do_test where2-4.6b {
  177. queryplan {
  178. SELECT * FROM t1
  179. WHERE x IN (1,2,3,4,5,6,7,8)
  180. AND y IN (10000,10001,10002,10003,10004,10005)
  181. ORDER BY x DESC
  182. }
  183. } {99 6 10000 10006 nosort t1 i1xy}
  184. do_test where2-4.6c {
  185. queryplan {
  186. SELECT * FROM t1
  187. WHERE x IN (1,2,3,4,5,6,7,8)
  188. AND y IN (10000,10001,10002,10003,10004,10005)
  189. ORDER BY x, y
  190. }
  191. } {99 6 10000 10006 nosort t1 i1xy}
  192. do_test where2-4.6d {
  193. queryplan {
  194. SELECT * FROM t1
  195. WHERE x IN (1,2,3,4,5,6,7,8)
  196. AND y IN (10000,10001,10002,10003,10004,10005)
  197. ORDER BY x, y DESC
  198. }
  199. } {99 6 10000 10006 sort t1 i1xy}
  200. # Duplicate entires on the RHS of an IN operator do not cause duplicate
  201. # output rows.
  202. #
  203. do_test where2-4.6x {
  204. queryplan {
  205. SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207)
  206. ORDER BY w
  207. }
  208. } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
  209. do_test where2-4.6y {
  210. queryplan {
  211. SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207)
  212. ORDER BY w DESC
  213. }
  214. } {100 6 10201 10207 99 6 10000 10006 sort t1 i1zyx}
  215. ifcapable compound {
  216. do_test where2-4.7 {
  217. queryplan {
  218. SELECT * FROM t1 WHERE z IN (
  219. SELECT 10207 UNION ALL SELECT 10006
  220. UNION ALL SELECT 10006 UNION ALL SELECT 10207)
  221. ORDER BY w
  222. }
  223. } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
  224. }
  225. } ;# ifcapable subquery
  226. # The use of an IN operator disables the index as a sorter.
  227. #
  228. do_test where2-5.1 {
  229. queryplan {
  230. SELECT * FROM t1 WHERE w=99 ORDER BY w
  231. }
  232. } {99 6 10000 10006 nosort t1 i1w}
  233. ifcapable subquery {
  234. do_test where2-5.2a {
  235. queryplan {
  236. SELECT * FROM t1 WHERE w IN (99) ORDER BY w
  237. }
  238. } {99 6 10000 10006 nosort t1 i1w}
  239. do_test where2-5.2b {
  240. queryplan {
  241. SELECT * FROM t1 WHERE w IN (99) ORDER BY w DESC
  242. }
  243. } {99 6 10000 10006 nosort t1 i1w}
  244. }
  245. # Verify that OR clauses get translated into IN operators.
  246. #
  247. set ::idx {}
  248. ifcapable subquery {set ::idx i1w}
  249. do_test where2-6.1.1 {
  250. queryplan {
  251. SELECT * FROM t1 WHERE w=99 OR w=100 ORDER BY +w
  252. }
  253. } [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
  254. do_test where2-6.1.2 {
  255. queryplan {
  256. SELECT * FROM t1 WHERE 99=w OR 100=w ORDER BY +w
  257. }
  258. } [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
  259. do_test where2-6.2 {
  260. queryplan {
  261. SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=w ORDER BY +w
  262. }
  263. } [list 6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
  264. do_test where2-6.3 {
  265. queryplan {
  266. SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=+w ORDER BY +w
  267. }
  268. } {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 *}
  269. do_test where2-6.4 {
  270. queryplan {
  271. SELECT * FROM t1 WHERE w=99 OR +w=100 OR 6=w ORDER BY +w
  272. }
  273. } {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 *}
  274. set ::idx {}
  275. ifcapable subquery {set ::idx i1zyx}
  276. do_test where2-6.5 {
  277. queryplan {
  278. SELECT b.* FROM t1 a, t1 b
  279. WHERE a.w=1 AND (a.y=b.z OR b.z=10)
  280. ORDER BY +b.w
  281. }
  282. } [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
  283. do_test where2-6.6 {
  284. queryplan {
  285. SELECT b.* FROM t1 a, t1 b
  286. WHERE a.w=1 AND (b.z=10 OR a.y=b.z OR b.z=10)
  287. ORDER BY +b.w
  288. }
  289. } [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
  290. if {[permutation] != "no_optimization"} {
  291. # Ticket #2249. Make sure the OR optimization is not attempted if
  292. # comparisons between columns of different affinities are needed.
  293. #
  294. do_test where2-6.7 {
  295. execsql {
  296. CREATE TABLE t2249a(a TEXT UNIQUE, x CHAR(100));
  297. CREATE TABLE t2249b(b INTEGER);
  298. INSERT INTO t2249a(a) VALUES('0123');
  299. INSERT INTO t2249b VALUES(123);
  300. }
  301. queryplan {
  302. -- Because a is type TEXT and b is type INTEGER, both a and b
  303. -- will attempt to convert to NUMERIC before the comparison.
  304. -- They will thus compare equal.
  305. --
  306. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b;
  307. }
  308. } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  309. do_test where2-6.9 {
  310. queryplan {
  311. -- The + operator removes affinity from the rhs. No conversions
  312. -- occur and the comparison is false. The result is an empty set.
  313. --
  314. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b;
  315. }
  316. } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  317. do_test where2-6.9.2 {
  318. # The same thing but with the expression flipped around.
  319. queryplan {
  320. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a
  321. }
  322. } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  323. do_test where2-6.10 {
  324. queryplan {
  325. -- Use + on both sides of the comparison to disable indices
  326. -- completely. Make sure we get the same result.
  327. --
  328. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +a=+b;
  329. }
  330. } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  331. do_test where2-6.11 {
  332. # This will not attempt the OR optimization because of the a=b
  333. # comparison.
  334. queryplan {
  335. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b OR a='hello';
  336. }
  337. } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  338. do_test where2-6.11.2 {
  339. # Permutations of the expression terms.
  340. queryplan {
  341. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE b=a OR a='hello';
  342. }
  343. } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  344. do_test where2-6.11.3 {
  345. # Permutations of the expression terms.
  346. queryplan {
  347. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE 'hello'=a OR b=a;
  348. }
  349. } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  350. do_test where2-6.11.4 {
  351. # Permutations of the expression terms.
  352. queryplan {
  353. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR b=a;
  354. }
  355. } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  356. ifcapable explain&&subquery {
  357. # These tests are not run if subquery support is not included in the
  358. # build. This is because these tests test the "a = 1 OR a = 2" to
  359. # "a IN (1, 2)" optimisation transformation, which is not enabled if
  360. # subqueries and the IN operator is not available.
  361. #
  362. do_test where2-6.12 {
  363. # In this case, the +b disables the affinity conflict and allows
  364. # the OR optimization to be used again. The result is now an empty
  365. # set, the same as in where2-6.9.
  366. queryplan {
  367. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR a='hello';
  368. }
  369. } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  370. do_test where2-6.12.2 {
  371. # In this case, the +b disables the affinity conflict and allows
  372. # the OR optimization to be used again. The result is now an empty
  373. # set, the same as in where2-6.9.
  374. queryplan {
  375. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR +b=a;
  376. }
  377. } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  378. do_test where2-6.12.3 {
  379. # In this case, the +b disables the affinity conflict and allows
  380. # the OR optimization to be used again. The result is now an empty
  381. # set, the same as in where2-6.9.
  382. queryplan {
  383. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a OR a='hello';
  384. }
  385. } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  386. do_test where2-6.13 {
  387. # The addition of +a on the second term disabled the OR optimization.
  388. # But we should still get the same empty-set result as in where2-6.9.
  389. queryplan {
  390. SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR +a='hello';
  391. }
  392. } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
  393. }
  394. # Variations on the order of terms in a WHERE clause in order
  395. # to make sure the OR optimizer can recognize them all.
  396. do_test where2-6.20 {
  397. queryplan {
  398. SELECT x.a, y.a FROM t2249a x CROSS JOIN t2249a y WHERE x.a=y.a
  399. }
  400. } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
  401. ifcapable explain&&subquery {
  402. # These tests are not run if subquery support is not included in the
  403. # build. This is because these tests test the "a = 1 OR a = 2" to
  404. # "a IN (1, 2)" optimisation transformation, which is not enabled if
  405. # subqueries and the IN operator is not available.
  406. #
  407. do_test where2-6.21 {
  408. queryplan {
  409. SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
  410. WHERE x.a=y.a OR y.a='hello'
  411. }
  412. } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
  413. do_test where2-6.22 {
  414. queryplan {
  415. SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
  416. WHERE y.a=x.a OR y.a='hello'
  417. }
  418. } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
  419. do_test where2-6.23 {
  420. queryplan {
  421. SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
  422. WHERE y.a='hello' OR x.a=y.a
  423. }
  424. } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
  425. }
  426. # Unique queries (queries that are guaranteed to return only a single
  427. # row of result) do not call the sorter. But all tables must give
  428. # a unique result. If any one table in the join does not give a unique
  429. # result then sorting is necessary.
  430. #
  431. do_test where2-7.1 {
  432. cksort {
  433. create table t8(a unique, b, c);
  434. insert into t8 values(1,2,3);
  435. insert into t8 values(2,3,4);
  436. create table t9(x,y);
  437. insert into t9 values(2,4);
  438. insert into t9 values(2,3);
  439. select y from t8, t9 where a=1 order by a, y;
  440. }
  441. } {3 4 sort}
  442. do_test where2-7.2 {
  443. cksort {
  444. select * from t8 where a=1 order by b, c
  445. }
  446. } {1 2 3 nosort}
  447. do_test where2-7.3 {
  448. cksort {
  449. select * from t8, t9 where a=1 and y=3 order by b, x
  450. }
  451. } {1 2 3 2 3 sort}
  452. do_test where2-7.4 {
  453. cksort {
  454. create unique index i9y on t9(y);
  455. select * from t8, t9 where a=1 and y=3 order by b, x
  456. }
  457. } {1 2 3 2 3 nosort}
  458. } ;# if {[permutation] != "no_optimization"}
  459. # Ticket #1807. Using IN constrains on multiple columns of
  460. # a multi-column index.
  461. #
  462. ifcapable subquery {
  463. do_test where2-8.1 {
  464. execsql {
  465. SELECT * FROM t1 WHERE x IN (20,21) AND y IN (1,2)
  466. }
  467. } {}
  468. do_test where2-8.2 {
  469. execsql {
  470. SELECT * FROM t1 WHERE x IN (1,2) AND y IN (-5,-6)
  471. }
  472. } {}
  473. execsql {CREATE TABLE tx AS SELECT * FROM t1}
  474. do_test where2-8.3 {
  475. execsql {
  476. SELECT w FROM t1
  477. WHERE x IN (SELECT x FROM tx WHERE rowid<0)
  478. AND +y IN (SELECT y FROM tx WHERE rowid=1)
  479. }
  480. } {}
  481. do_test where2-8.4 {
  482. execsql {
  483. SELECT w FROM t1
  484. WHERE x IN (SELECT x FROM tx WHERE rowid=1)
  485. AND y IN (SELECT y FROM tx WHERE rowid<0)
  486. }
  487. } {}
  488. #set sqlite_where_trace 1
  489. do_test where2-8.5 {
  490. execsql {
  491. CREATE INDEX tx_xyz ON tx(x, y, z, w);
  492. SELECT w FROM tx
  493. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
  494. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
  495. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 12 AND 14)
  496. }
  497. } {12 13 14}
  498. do_test where2-8.6 {
  499. execsql {
  500. SELECT w FROM tx
  501. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
  502. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 12 AND 14)
  503. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
  504. }
  505. } {12 13 14}
  506. do_test where2-8.7 {
  507. execsql {
  508. SELECT w FROM tx
  509. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 12 AND 14)
  510. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
  511. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
  512. }
  513. } {10 11 12 13 14 15}
  514. do_test where2-8.8 {
  515. execsql {
  516. SELECT w FROM tx
  517. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
  518. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
  519. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
  520. }
  521. } {10 11 12 13 14 15 16 17 18 19 20}
  522. do_test where2-8.9 {
  523. execsql {
  524. SELECT w FROM tx
  525. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
  526. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
  527. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 2 AND 4)
  528. }
  529. } {}
  530. do_test where2-8.10 {
  531. execsql {
  532. SELECT w FROM tx
  533. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
  534. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 2 AND 4)
  535. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
  536. }
  537. } {}
  538. do_test where2-8.11 {
  539. execsql {
  540. SELECT w FROM tx
  541. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 2 AND 4)
  542. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
  543. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
  544. }
  545. } {}
  546. do_test where2-8.12 {
  547. execsql {
  548. SELECT w FROM tx
  549. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
  550. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
  551. AND z IN (SELECT z FROM t1 WHERE w BETWEEN -4 AND -2)
  552. }
  553. } {}
  554. do_test where2-8.13 {
  555. execsql {
  556. SELECT w FROM tx
  557. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
  558. AND y IN (SELECT y FROM t1 WHERE w BETWEEN -4 AND -2)
  559. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
  560. }
  561. } {}
  562. do_test where2-8.14 {
  563. execsql {
  564. SELECT w FROM tx
  565. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN -4 AND -2)
  566. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
  567. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
  568. }
  569. } {}
  570. do_test where2-8.15 {
  571. execsql {
  572. SELECT w FROM tx
  573. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
  574. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
  575. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 200 AND 300)
  576. }
  577. } {}
  578. do_test where2-8.16 {
  579. execsql {
  580. SELECT w FROM tx
  581. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
  582. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 200 AND 300)
  583. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
  584. }
  585. } {}
  586. do_test where2-8.17 {
  587. execsql {
  588. SELECT w FROM tx
  589. WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 200 AND 300)
  590. AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
  591. AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
  592. }
  593. } {}
  594. do_test where2-8.18 {
  595. execsql {
  596. SELECT w FROM tx
  597. WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
  598. AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
  599. AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 200 AND 300)
  600. }
  601. } {}
  602. do_test where2-8.19 {
  603. execsql {
  604. SELECT w FROM tx
  605. WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
  606. AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 200 AND 300)
  607. AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
  608. }
  609. } {}
  610. do_test where2-8.20 {
  611. execsql {
  612. SELECT w FROM tx
  613. WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 200 AND 300)
  614. AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
  615. AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
  616. }
  617. } {}
  618. }
  619. # Make sure WHERE clauses of the form A=1 AND (B=2 OR B=3) are optimized
  620. # when we have an index on A and B.
  621. #
  622. ifcapable or_opt&&tclvar {
  623. do_test where2-9.1 {
  624. execsql {
  625. BEGIN;
  626. CREATE TABLE t10(a,b,c);
  627. INSERT INTO t10 VALUES(1,1,1);
  628. INSERT INTO t10 VALUES(1,2,2);
  629. INSERT INTO t10 VALUES(1,3,3);
  630. }
  631. for {set i 4} {$i<=1000} {incr i} {
  632. execsql {INSERT INTO t10 VALUES(1,$i,$i)}
  633. }
  634. execsql {
  635. CREATE INDEX i10 ON t10(a,b);
  636. COMMIT;
  637. SELECT count(*) FROM t10;
  638. }
  639. } 1000
  640. ifcapable subquery {
  641. do_test where2-9.2 {
  642. count {
  643. SELECT * FROM t10 WHERE a=1 AND (b=2 OR b=3)
  644. }
  645. } {1 2 2 1 3 3 7}
  646. }
  647. }
  648. # Indices with redundant columns
  649. #
  650. do_test where2-11.1 {
  651. execsql {
  652. CREATE TABLE t11(a,b,c,d);
  653. CREATE INDEX i11aba ON t11(a,b,a,c); -- column A occurs twice.
  654. INSERT INTO t11 VALUES(1,2,3,4);
  655. INSERT INTO t11 VALUES(5,6,7,8);
  656. INSERT INTO t11 VALUES(1,2,9,10);
  657. INSERT INTO t11 VALUES(5,11,12,13);
  658. SELECT c FROM t11 WHERE a=1 AND b=2 ORDER BY c;
  659. }
  660. } {3 9}
  661. do_test where2-11.2 {
  662. execsql {
  663. CREATE INDEX i11cccccccc ON t11(c,c,c,c,c,c,c,c); -- repeated column
  664. SELECT d FROM t11 WHERE c=9;
  665. }
  666. } {10}
  667. do_test where2-11.3 {
  668. execsql {
  669. SELECT d FROM t11 WHERE c IN (1,2,3,4,5);
  670. }
  671. } {4}
  672. do_test where2-11.4 {
  673. execsql {
  674. SELECT d FROM t11 WHERE c=7 OR (a=1 AND b=2) ORDER BY d;
  675. }
  676. } {4 8 10}
  677. # Verify that the OR clause is used in an outer loop even when
  678. # the OR clause scores slightly better on an inner loop.
  679. if {[permutation] != "no_optimization"} {
  680. do_execsql_test where2-12.1 {
  681. CREATE TABLE t12(x INTEGER PRIMARY KEY, y INT, z CHAR(100));
  682. CREATE INDEX t12y ON t12(y);
  683. EXPLAIN QUERY PLAN
  684. SELECT a.x, b.x
  685. FROM t12 AS a JOIN t12 AS b ON a.y=b.x
  686. WHERE (b.x=$abc OR b.y=$abc);
  687. } {/.*SEARCH TABLE t12 AS b .*SEARCH TABLE t12 AS b .*/}
  688. }
  689. finish_test