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.4 2005/07/29 19:43:59 drh Exp $ 16 17set testdir [file dirname $argv0] 18source $testdir/tester.tcl 19 20# Build some test data 21# 22do_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}] 32 execsql {INSERT INTO t1 VALUES($::w,$::x,$::y,$::z)} 33 } 34 execsql { 35 CREATE UNIQUE INDEX i1w ON t1(w); 36 CREATE INDEX i1xy ON t1(x,y); 37 CREATE INDEX i1zyx ON t1(z,y,x); 38 COMMIT; 39 } 40} {} 41 42# Do an SQL statement. Append the search count to the end of the result. 43# 44proc count sql { 45 set ::sqlite_search_count 0 46 return [concat [execsql $sql] $::sqlite_search_count] 47} 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# 56proc cksort {sql} { 57 set ::sqlite_sort_count 0 58 set data [execsql $sql] 59 if {$::sqlite_sort_count} {set x sort} {set x nosort} 60 lappend data $x 61 return $data 62} 63 64# This procedure executes the SQL. Then it appends to the result the 65# "sort" or "nosort" keyword (as in the cksort procedure above) then 66# it appends the ::sqlite_query_plan variable. 67# 68proc queryplan {sql} { 69 set ::sqlite_sort_count 0 70 set data [execsql $sql] 71 if {$::sqlite_sort_count} {set x sort} {set x nosort} 72 lappend data $x 73 return [concat $data $::sqlite_query_plan] 74} 75 76 77# Prefer a UNIQUE index over another index. 78# 79do_test where2-1.1 { 80 queryplan { 81 SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396 82 } 83} {85 6 7396 7402 nosort t1 i1w} 84 85# Always prefer a rowid== constraint over any other index. 86# 87do_test where2-1.3 { 88 queryplan { 89 SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396 AND rowid=85 90 } 91} {85 6 7396 7402 nosort t1 *} 92 93# When constrained by a UNIQUE index, the ORDER BY clause is always ignored. 94# 95do_test where2-2.1 { 96 queryplan { 97 SELECT * FROM t1 WHERE w=85 ORDER BY random(5); 98 } 99} {85 6 7396 7402 nosort t1 i1w} 100do_test where2-2.2 { 101 queryplan { 102 SELECT * FROM t1 WHERE x=6 AND y=7396 ORDER BY random(5); 103 } 104} {85 6 7396 7402 sort t1 i1xy} 105do_test where2-2.3 { 106 queryplan { 107 SELECT * FROM t1 WHERE rowid=85 AND x=6 AND y=7396 ORDER BY random(5); 108 } 109} {85 6 7396 7402 nosort t1 *} 110 111 112# Efficient handling of forward and reverse table scans. 113# 114do_test where2-3.1 { 115 queryplan { 116 SELECT * FROM t1 ORDER BY rowid LIMIT 2 117 } 118} {1 0 4 4 2 1 9 10 nosort t1 *} 119do_test where2-3.2 { 120 queryplan { 121 SELECT * FROM t1 ORDER BY rowid DESC LIMIT 2 122 } 123} {100 6 10201 10207 99 6 10000 10006 nosort t1 *} 124 125# The IN operator can be used by indices at multiple layers 126# 127do_test where2-4.1 { 128 queryplan { 129 SELECT * FROM t1 WHERE z IN (10207,10006) AND y IN (10000,10201) 130 AND x>0 AND x<10 131 ORDER BY w 132 } 133} {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx} 134do_test where2-4.2 { 135 queryplan { 136 SELECT * FROM t1 WHERE z IN (10207,10006) AND y=10000 137 AND x>0 AND x<10 138 ORDER BY w 139 } 140} {99 6 10000 10006 sort t1 i1zyx} 141do_test where2-4.3 { 142 queryplan { 143 SELECT * FROM t1 WHERE z=10006 AND y IN (10000,10201) 144 AND x>0 AND x<10 145 ORDER BY w 146 } 147} {99 6 10000 10006 sort t1 i1zyx} 148do_test where2-4.4 { 149 queryplan { 150 SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006) 151 AND y IN (10000,10201) 152 AND x>0 AND x<10 153 ORDER BY w 154 } 155} {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx} 156do_test where2-4.5 { 157 queryplan { 158 SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006) 159 AND y IN (SELECT 10000 UNION SELECT 10201) 160 AND x>0 AND x<10 161 ORDER BY w 162 } 163} {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx} 164do_test where2-4.6 { 165 queryplan { 166 SELECT * FROM t1 167 WHERE x IN (1,2,3,4,5,6,7,8) 168 AND y IN (10000,10001,10002,10003,10004,10005) 169 ORDER BY 2 170 } 171} {99 6 10000 10006 sort t1 i1xy} 172 173# Duplicate entires on the RHS of an IN operator do not cause duplicate 174# output rows. 175# 176do_test where2-4.6 { 177 queryplan { 178 SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207) 179 ORDER BY w 180 } 181} {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx} 182do_test where2-4.7 { 183 queryplan { 184 SELECT * FROM t1 WHERE z IN ( 185 SELECT 10207 UNION ALL SELECT 10006 186 UNION ALL SELECT 10006 UNION ALL SELECT 10207) 187 ORDER BY w 188 } 189} {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx} 190 191# The use of an IN operator disables the index as a sorter. 192# 193do_test where2-5.1 { 194 queryplan { 195 SELECT * FROM t1 WHERE w=99 ORDER BY w 196 } 197} {99 6 10000 10006 nosort t1 i1w} 198do_test where2-5.2 { 199 queryplan { 200 SELECT * FROM t1 WHERE w IN (99) ORDER BY w 201 } 202} {99 6 10000 10006 sort t1 i1w} 203 204# Verify that OR clauses get translated into IN operators. 205# 206do_test where2-6.1 { 207 queryplan { 208 SELECT * FROM t1 WHERE w=99 OR w=100 ORDER BY +w 209 } 210} {99 6 10000 10006 100 6 10201 10207 sort t1 i1w} 211do_test where2-6.2 { 212 queryplan { 213 SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=w ORDER BY +w 214 } 215} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 i1w} 216do_test where2-6.3 { 217 queryplan { 218 SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=+w ORDER BY +w 219 } 220} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 {}} 221do_test where2-6.4 { 222 queryplan { 223 SELECT * FROM t1 WHERE w=99 OR +w=100 OR 6=w ORDER BY +w 224 } 225} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 {}} 226do_test where2-6.5 { 227 queryplan { 228 SELECT b.* FROM t1 a, t1 b 229 WHERE a.w=1 AND (a.y=b.z OR b.z=10) 230 ORDER BY +b.w 231 } 232} {1 0 4 4 2 1 9 10 sort a i1w b i1zyx} 233do_test where2-6.6 { 234 queryplan { 235 SELECT b.* FROM t1 a, t1 b 236 WHERE a.w=1 AND (b.z=10 OR a.y=b.z OR b.z=10) 237 ORDER BY +b.w 238 } 239} {1 0 4 4 2 1 9 10 sort a i1w b i1zyx} 240 241 242 243finish_test 244