Do not consider a DISTINCT clause redundant unless a subset of the result-set is collectively subject to a UNIQUE constraint and it can be guaranteed that all columns of the subset are NOT NULL (either due to NOT NULL constraints WHERE clause terms). Fix for [385a5b56b9].

FossilOrigin-Name: 7b8548b1872cc1225355ba8311e93dd08d6526e2
This commit is contained in:
dan 2012-04-20 16:59:24 +00:00
parent 99f8fb66a4
commit 6a36f43586
5 changed files with 95 additions and 23 deletions

View File

@ -1,5 +1,5 @@
C Fix\sfor\s2a5629202f.\sWhen\sconsidering\swhether\sor\snot\sa\sUNIQUE\sindex\smay\sbe\sused\sto\soptimize\san\sORDER\sBY\sclause,\sdo\snot\sassume\sthat\sall\sindex\sentries\sare\sdistinct\sunless\sthere\sis\ssome\sreason\sto\sbelieve\sthat\sthe\sindex\scontains\sno\sNULL\svalues.
D 2012-04-20T15:24:53.110
C Do\snot\sconsider\sa\sDISTINCT\sclause\sredundant\sunless\sa\ssubset\sof\sthe\sresult-set\sis\scollectively\ssubject\sto\sa\sUNIQUE\sconstraint\sand\sit\scan\sbe\sguaranteed\sthat\sall\scolumns\sof\sthe\ssubset\sare\sNOT\sNULL\s(either\sdue\sto\sNOT\sNULL\sconstraints\sWHERE\sclause\sterms).\sFix\sfor\s[385a5b56b9].
D 2012-04-20T16:59:24.885
F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f
F Makefile.in 2f37e468503dbe79d35c9f6dffcf3fae1ae9ec20
F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23
@ -246,7 +246,7 @@ F src/vtab.c ab90fb600a3f5e4b7c48d22a4cdb2d6b23239847
F src/wal.c 7bb3ad807afc7973406c805d5157ec7a2f65e146
F src/wal.h 29c197540b19044e6cd73487017e5e47a1d3dac6
F src/walker.c 3112bb3afe1d85dc52317cb1d752055e9a781f8f
F src/where.c e25ae482e94226df7f95fa4e0545cc7064e86574
F src/where.c 8e9f01cd1604aa21cfa8e0258b7101e05082fa98
F test/8_3_names.test 631ea964a3edb091cf73c3b540f6bcfdb36ce823
F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2
F test/alias.test 4529fbc152f190268a15f9384a5651bbbabc9d87
@ -368,7 +368,7 @@ F test/descidx1.test 533dcbda614b0463b0ea029527fd27e5a9ab2d66
F test/descidx2.test 9f1a0c83fd57f8667c82310ca21b30a350888b5d
F test/descidx3.test fe720e8b37d59f4cef808b0bf4e1b391c2e56b6f
F test/diskfull.test 106391384780753ea6896b7b4f005d10e9866b6e
F test/distinct.test 8c6d12ba53ee8351a5b2d47628acdfad1fc97743
F test/distinct.test da36612d05b9ed17e0425d4bfd7ab978d28a7e46
F test/distinctagg.test 1a6ef9c87a58669438fc771450d7a72577417376
F test/e_createtable.test 48598b15e8fe6554d301e7b65a10c9851f177e84
F test/e_delete.test 89aa84d3d1bd284a0689ede04bce10226a5aeaa5
@ -738,6 +738,7 @@ F test/tkt-2d1a5c67d.test b028a811049eb472cb2d3a43fc8ce4f6894eebda
F test/tkt-2ea2425d34.test 1cf13e6f75d149b3209a0cb32927a82d3d79fb28
F test/tkt-31338dca7e.test 1f714c14b6682c5db715e0bda347926a3456f7a9
F test/tkt-313723c356.test c47f8a9330523e6f35698bf4489bcb29609b53ac
F test/tkt-385a5b56b9.test 8eb87c4bbcc3fd4f33d73719de7e9d64973fa196
F test/tkt-38cb5df375.test f3cc8671f1eb604d4ae9cf886ed4366bec656678
F test/tkt-3998683a16.test 6d1d04d551ed1704eb3396ca87bb9ccc8c5c1eb7
F test/tkt-3a77c9714e.test 32bb28afa8c63fc76e972e996193139b63551ed9
@ -993,7 +994,7 @@ F tool/tostr.awk e75472c2f98dd76e06b8c9c1367f4ab07e122d06
F tool/vdbe-compress.tcl d70ea6d8a19e3571d7ab8c9b75cba86d1173ff0f
F tool/warnings-clang.sh a8a0a3babda96dfb1ff51adda3cbbf3dfb7266c2
F tool/warnings.sh fbc018d67fd7395f440c28f33ef0f94420226381
P 372a90e2264a29ce543c093766cdec764d18b5a5
R c55b0e9d6060c081eba144f695f549a1
P 9870e4c4fef10112c987c40cb1b95255a7214202
R 7b0d4f32973f40703f4feb63496b017b
U dan
Z 3f4edf7c59f1f66ed37303deb846aef3
Z 293167d92a8f749c1bd20f8cdd573739

View File

@ -1 +1 @@
9870e4c4fef10112c987c40cb1b95255a7214202
7b8548b1872cc1225355ba8311e93dd08d6526e2

View File

@ -1562,15 +1562,19 @@ static int isDistinctRedundant(
** list, or else the WHERE clause contains a term of the form "col=X",
** where X is a constant value. The collation sequences of the
** comparison and select-list expressions must match those of the index.
**
** 3. All of those index columns for which the WHERE clause does not
** contain a "col=X" term are subject to a NOT NULL constraint.
*/
for(pIdx=pTab->pIndex; pIdx; pIdx=pIdx->pNext){
if( pIdx->onError==OE_None ) continue;
for(i=0; i<pIdx->nColumn; i++){
int iCol = pIdx->aiColumn[i];
if( 0==findTerm(pWC, iBase, iCol, ~(Bitmask)0, WO_EQ, pIdx)
&& 0>findIndexCol(pParse, pDistinct, iBase, pIdx, i)
){
break;
if( 0==findTerm(pWC, iBase, iCol, ~(Bitmask)0, WO_EQ, pIdx) ){
int iIdxCol = findIndexCol(pParse, pDistinct, iBase, pIdx, i);
if( iIdxCol<0 || pTab->aCol[pIdx->aiColumn[i]].notNull==0 ){
break;
}
}
}
if( i==pIdx->nColumn ){
@ -1737,7 +1741,7 @@ static int isSortingIndex(
for(i=nEqCol; i<pIdx->nColumn; i++){
if( aCol[pIdx->aiColumn[i]].notNull==0 ) break;
}
return (i>=pIdx->nColumn);
return (i==pIdx->nColumn);
}
return 0;
}

View File

@ -77,20 +77,27 @@ do_execsql_test 1.0 {
CREATE TABLE t2(x INTEGER PRIMARY KEY, y);
CREATE TABLE t3(c1 PRIMARY KEY, c2);
CREATE TABLE t3(c1 PRIMARY KEY NOT NULL, c2 NOT NULL);
CREATE INDEX i3 ON t3(c2);
CREATE TABLE t4(a, b NOT NULL, c NOT NULL, d NOT NULL);
CREATE UNIQUE INDEX t4i1 ON t4(b, c);
CREATE UNIQUE INDEX t4i2 ON t4(d COLLATE nocase);
}
foreach {tn noop sql} {
1 1 "SELECT DISTINCT b, c FROM t1"
2 1 "SELECT DISTINCT c FROM t1 WHERE b = ?"
1.1 0 "SELECT DISTINCT b, c FROM t1"
1.2 1 "SELECT DISTINCT b, c FROM t4"
2.1 0 "SELECT DISTINCT c FROM t1 WHERE b = ?"
2.2 1 "SELECT DISTINCT c FROM t4 WHERE b = ?"
3 1 "SELECT DISTINCT rowid FROM t1"
4 1 "SELECT DISTINCT rowid, a FROM t1"
5 1 "SELECT DISTINCT x FROM t2"
6 1 "SELECT DISTINCT * FROM t2"
7 1 "SELECT DISTINCT * FROM (SELECT * FROM t2)"
8 1 "SELECT DISTINCT * FROM t1"
8.1 0 "SELECT DISTINCT * FROM t1"
8.2 1 "SELECT DISTINCT * FROM t4"
8 0 "SELECT DISTINCT a, b FROM t1"
@ -98,11 +105,16 @@ foreach {tn noop sql} {
10 0 "SELECT DISTINCT c FROM t1"
11 0 "SELECT DISTINCT b FROM t1"
12 0 "SELECT DISTINCT a, d FROM t1"
13 0 "SELECT DISTINCT a, b, c COLLATE nocase FROM t1"
14 1 "SELECT DISTINCT a, d COLLATE nocase FROM t1"
15 0 "SELECT DISTINCT a, d COLLATE binary FROM t1"
16 1 "SELECT DISTINCT a, b, c COLLATE binary FROM t1"
12.1 0 "SELECT DISTINCT a, d FROM t1"
12.2 0 "SELECT DISTINCT a, d FROM t4"
13.1 0 "SELECT DISTINCT a, b, c COLLATE nocase FROM t1"
13.2 0 "SELECT DISTINCT a, b, c COLLATE nocase FROM t4"
14.1 0 "SELECT DISTINCT a, d COLLATE nocase FROM t1"
14.2 1 "SELECT DISTINCT a, d COLLATE nocase FROM t4"
15 0 "SELECT DISTINCT a, d COLLATE binary FROM t1"
16.1 0 "SELECT DISTINCT a, b, c COLLATE binary FROM t1"
16.2 1 "SELECT DISTINCT a, b, c COLLATE binary FROM t4"
16 0 "SELECT DISTINCT t1.rowid FROM t1, t2"
17 0 { /* Technically, it would be possible to detect that DISTINCT
@ -120,7 +132,8 @@ foreach {tn noop sql} {
24 0 "SELECT DISTINCT rowid/2 FROM t1"
25 1 "SELECT DISTINCT rowid/2, rowid FROM t1"
26 1 "SELECT DISTINCT rowid/2, b FROM t1 WHERE c = ?"
26.1 0 "SELECT DISTINCT rowid/2, b FROM t1 WHERE c = ?"
26.2 1 "SELECT DISTINCT rowid/2, b FROM t4 WHERE c = ?"
} {
if {$noop} {
do_distinct_noop_test 1.$tn $sql

54
test/tkt-385a5b56b9.test Normal file
View File

@ -0,0 +1,54 @@
# 2012 April 02
#
# The author disclaims copyright to this source code. In place of
# a legal notice, here is a blessing:
#
# May you do good and not evil.
# May you find forgiveness for yourself and forgive others.
# May you share freely, never taking more than you give.
#
#***********************************************************************
# The tests in this file were used while developing the SQLite 4 code.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
set testprefix tkt-385a5b56b9
do_execsql_test 1.0 {
CREATE TABLE t1(x, y);
INSERT INTO t1 VALUES(1, NULL);
INSERT INTO t1 VALUES(2, NULL);
INSERT INTO t1 VALUES(1, NULL);
}
do_execsql_test 1.1 { SELECT DISTINCT x, y FROM t1 } {1 {} 2 {}}
do_execsql_test 1.2 { CREATE UNIQUE INDEX i1 ON t1(x, y) }
do_execsql_test 1.3 { SELECT DISTINCT x, y FROM t1 } {1 {} 2 {}}
#-------------------------------------------------------------------------
do_execsql_test 2.0 {
CREATE TABLE t2(x, y NOT NULL);
CREATE UNIQUE INDEX t2x ON t2(x);
CREATE UNIQUE INDEX t2y ON t2(y);
}
do_eqp_test 2.1 { SELECT DISTINCT x FROM t2 } {
0 0 0 {SCAN TABLE t2 USING COVERING INDEX t2x (~1000000 rows)}
}
do_eqp_test 2.2 { SELECT DISTINCT y FROM t2 } {
0 0 0 {SCAN TABLE t2 (~1000000 rows)}
}
do_eqp_test 2.3 { SELECT DISTINCT x, y FROM t2 WHERE y=10 } {
0 0 0 {SEARCH TABLE t2 USING INDEX t2y (y=?) (~1 rows)}
}
do_eqp_test 2.4 { SELECT DISTINCT x, y FROM t2 WHERE x=10 } {
0 0 0 {SEARCH TABLE t2 USING INDEX t2x (x=?) (~1 rows)}
}
finish_test