From 4a1aa3851aeceef8e027d35751008b89ca4c62d4 Mon Sep 17 00:00:00 2001 From: dan Date: Sat, 31 Aug 2013 17:21:26 +0000 Subject: [PATCH] Fix a problem causing SQLite not to use stat4 or stat3 data to analyze constraints of the form "column = expr COLLATE collation" (those with an explicit COLLATE on the non-column side of the comparison operator). FossilOrigin-Name: 1e86d81d46c9da6aaee0c6938ee40933f35e3d0d --- manifest | 14 ++--- manifest.uuid | 2 +- src/vdbemem.c | 3 + test/analyze9.test | 135 +++++++++++++++++++++++++++++++++++++++++++++ 4 files changed, 146 insertions(+), 8 deletions(-) diff --git a/manifest b/manifest index 4f6ffd175e..0b5fa83aa7 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Reenable\sa\stest\saccidentally\sdisabled\swhen\sthe\sstat4\sbranch\swas\smerged. -D 2013-08-31T14:56:30.692 +C Fix\sa\sproblem\scausing\sSQLite\snot\sto\suse\sstat4\sor\sstat3\sdata\sto\sanalyze\sconstraints\sof\sthe\sform\s"column\s=\sexpr\sCOLLATE\scollation"\s(those\swith\san\sexplicit\sCOLLATE\son\sthe\snon-column\sside\sof\sthe\scomparison\soperator). +D 2013-08-31T17:21:26.324 F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f F Makefile.in 5e41da95d92656a5004b03d3576e8b226858a28e F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23 @@ -283,7 +283,7 @@ F src/vdbeInt.h cbe71b8b36d8b3bba5709cc3f436c7e3b47b7b08 F src/vdbeapi.c 96b24b946cf21894f63d9393e821baa2f0a80979 F src/vdbeaux.c c7fe2695e256dbf254113c4fe90d3ec9aabe3bbe F src/vdbeblob.c 5dc79627775bd9a9b494dd956e26297946417d69 -F src/vdbemem.c 4511e1d2304a7d7916d14be20080036331740fcf +F src/vdbemem.c 75ad7fd8f068a8baaba1cf3a84714ef7d3b7a2b8 F src/vdbesort.c 3937e06b2a0e354500e17dc206ef4c35770a5017 F src/vdbetrace.c e7ec40e1999ff3c6414424365d5941178966dcbc F src/vtab.c 165ce0e797c2cd23badb104c9f2ae9042d6d942c @@ -308,7 +308,7 @@ F test/analyze5.test 765c4e284aa69ca172772aa940946f55629bc8c4 F test/analyze6.test 19151da2c4e918905d2081b74ac5c4d47fc850ab F test/analyze7.test bb1409afc9e8629e414387ef048b8e0e3e0bdc4f F test/analyze8.test 093d15c1c888eed5034304a98c992f7360130b88 -F test/analyze9.test 3095a9ebfea4a2b1f9db60375320ae7f219595ba +F test/analyze9.test 2bc3fb7b0ba7954e2513e69af8608ce5da201418 F test/analyzeA.test 1a5c40079894847976d983ca39c707aaa44b6944 F test/async.test 1d0e056ba1bb9729283a0f22718d3a25e82c277b F test/async2.test c0a9bd20816d7d6a2ceca7b8c03d3d69c28ffb8b @@ -1109,7 +1109,7 @@ F tool/warnings-clang.sh f6aa929dc20ef1f856af04a730772f59283631d4 F tool/warnings.sh fbc018d67fd7395f440c28f33ef0f94420226381 F tool/wherecosttest.c f407dc4c79786982a475261866a161cd007947ae F tool/win/sqlite.vsix 97894c2790eda7b5bce3cc79cb2a8ec2fde9b3ac -P 5bbd2ccb3d2d6286fd667dac2ab658d6b89640a6 -R 1451e706c75b3cfea10ed5a938fdd0ce +P d9fadc8fa6ef02d516678d57896d93e0a5f52cfe +R 549c9915be9450c721bff69cc42a239a U dan -Z 244a50a69073c5e2d4dc31f3118b8090 +Z dce49f1165decc3594690bec1fb4ef74 diff --git a/manifest.uuid b/manifest.uuid index ed7629c778..89b7c2ebb7 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -d9fadc8fa6ef02d516678d57896d93e0a5f52cfe \ No newline at end of file +1e86d81d46c9da6aaee0c6938ee40933f35e3d0d \ No newline at end of file diff --git a/src/vdbemem.c b/src/vdbemem.c index e6ad291532..dbdfc53074 100644 --- a/src/vdbemem.c +++ b/src/vdbemem.c @@ -1311,6 +1311,9 @@ int sqlite3Stat4ProbeSetValue( alloc.ppRec = ppRec; alloc.iVal = iVal; + /* Skip over any TK_COLLATE nodes */ + pExpr = sqlite3ExprSkipCollate(pExpr); + if( !pExpr ){ pVal = valueNew(pParse->db, &alloc); if( pVal ){ diff --git a/test/analyze9.test b/test/analyze9.test index be52eb94b2..e2528709bf 100644 --- a/test/analyze9.test +++ b/test/analyze9.test @@ -422,5 +422,140 @@ do_eqp_test 9.4.2 { SELECT * FROM t1 WHERE a='x' AND b='y' AND c='z' AND d=$value_d AND e=5 } {/t1 USING INDEX i1/} +#------------------------------------------------------------------------- +# Check that the planner takes stat4 data into account when considering +# "IS NULL" and "IS NOT NULL" constraints. +# +do_execsql_test 10.1.1 { + DROP TABLE IF EXISTS t3; + CREATE TABLE t3(a, b); + CREATE INDEX t3a ON t3(a); + CREATE INDEX t3b ON t3(b); +} +do_test 10.1.2 { + for {set i 1} {$i < 100} {incr i} { + if {$i>90} { set a $i } else { set a NULL } + set b [expr $i % 5] + execsql "INSERT INTO t3 VALUES($a, $b)" + } + execsql ANALYZE +} {} +do_eqp_test 10.1.3 { + SELECT * FROM t3 WHERE a IS NULL AND b = 2 +} {/t3 USING INDEX t3b/} +do_eqp_test 10.1.4 { + SELECT * FROM t3 WHERE a IS NOT NULL AND b = 2 +} {/t3 USING INDEX t3a/} + +do_execsql_test 10.2.1 { + DROP TABLE IF EXISTS t3; + CREATE TABLE t3(x, a, b); + CREATE INDEX t3a ON t3(x, a); + CREATE INDEX t3b ON t3(x, b); +} +do_test 10.2.2 { + for {set i 1} {$i < 100} {incr i} { + if {$i>90} { set a $i } else { set a NULL } + set b [expr $i % 5] + execsql "INSERT INTO t3 VALUES('xyz', $a, $b)" + } + execsql ANALYZE +} {} +do_eqp_test 10.2.3 { + SELECT * FROM t3 WHERE x = 'xyz' AND a IS NULL AND b = 2 +} {/t3 USING INDEX t3b/} +do_eqp_test 10.2.4 { + SELECT * FROM t3 WHERE x = 'xyz' AND a IS NOT NULL AND b = 2 +} {/t3 USING INDEX t3a/} + +#------------------------------------------------------------------------- +# Check that stat4 data is used correctly with non-default collation +# sequences. +# +foreach {tn schema} { + 1 { + CREATE TABLE t4(a COLLATE nocase, b); + CREATE INDEX t4a ON t4(a); + CREATE INDEX t4b ON t4(b); + } + 2 { + CREATE TABLE t4(a, b); + CREATE INDEX t4a ON t4(a COLLATE nocase); + CREATE INDEX t4b ON t4(b); + } +} { + drop_all_tables + do_test 11.$tn.1 { execsql $schema } {} + + do_test 11.$tn.2 { + for {set i 0} {$i < 100} {incr i} { + if { ($i % 10)==0 } { set a ABC } else { set a DEF } + set b [expr $i % 5] + execsql { INSERT INTO t4 VALUES($a, $b) } + } + execsql ANALYZE + } {} + + do_eqp_test 11.$tn.3 { + SELECT * FROM t4 WHERE a = 'def' AND b = 3; + } {/t4 USING INDEX t4b/} + + if {$tn==1} { + set sql "SELECT * FROM t4 WHERE a = 'abc' AND b = 3;" + do_eqp_test 11.$tn.4 $sql {/t4 USING INDEX t4a/} + } else { + + set sql "SELECT * FROM t4 WHERE a = 'abc' COLLATE nocase AND b = 3;" + do_eqp_test 11.$tn.5 $sql {/t4 USING INDEX t4a/} + + set sql "SELECT * FROM t4 WHERE a COLLATE nocase = 'abc' AND b = 3;" + do_eqp_test 11.$tn.6 $sql {/t4 USING INDEX t4a/} + } +} + +foreach {tn schema} { + 1 { + CREATE TABLE t4(x, a COLLATE nocase, b); + CREATE INDEX t4a ON t4(x, a); + CREATE INDEX t4b ON t4(x, b); + } + 2 { + CREATE TABLE t4(x, a, b); + CREATE INDEX t4a ON t4(x, a COLLATE nocase); + CREATE INDEX t4b ON t4(x, b); + } +} { + drop_all_tables + do_test 12.$tn.1 { execsql $schema } {} + + do_test 12.$tn.2 { + for {set i 0} {$i < 100} {incr i} { + if { ($i % 10)==0 } { set a ABC } else { set a DEF } + set b [expr $i % 5] + execsql { INSERT INTO t4 VALUES(X'abcdef', $a, $b) } + } + execsql ANALYZE + } {} + + do_eqp_test 12.$tn.3 { + SELECT * FROM t4 WHERE x=X'abcdef' AND a = 'def' AND b = 3; + } {/t4 USING INDEX t4b/} + + if {$tn==1} { + set sql "SELECT * FROM t4 WHERE x=X'abcdef' AND a = 'abc' AND b = 3;" + do_eqp_test 12.$tn.4 $sql {/t4 USING INDEX t4a/} + } else { + set sql { + SELECT * FROM t4 WHERE x=X'abcdef' AND a = 'abc' COLLATE nocase AND b = 3 + } + do_eqp_test 12.$tn.5 $sql {/t4 USING INDEX t4a/} + set sql { + SELECT * FROM t4 WHERE x=X'abcdef' AND a COLLATE nocase = 'abc' AND b = 3 + } + do_eqp_test 12.$tn.6 $sql {/t4 USING INDEX t4a/} + } +} + finish_test +