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