From: drh Date: Sat, 17 Sep 2005 13:07:13 +0000 (+0000) Subject: Make sure dependencies on the right-hand side of IN operators are checked X-Git-Tag: version-3.6.10~3454 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=f5b1138baef1958790ec0440ebff06ddbe78bbfd;p=thirdparty%2Fsqlite.git Make sure dependencies on the right-hand side of IN operators are checked correctly. Ticket #1433. (CVS 2706) FossilOrigin-Name: 21740794ab81924442f358a6adbbe6d5590cf58d --- diff --git a/manifest b/manifest index 798204e5ec..1f0347ee5c 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Updates\sto\sthe\sFAQ.\s(CVS\s2705) -D 2005-09-17T02:34:05 +C Make\ssure\sdependencies\son\sthe\sright-hand\sside\sof\sIN\soperators\sare\schecked\ncorrectly.\s\sTicket\s#1433.\s(CVS\s2706) +D 2005-09-17T13:07:13 F Makefile.in 12784cdce5ffc8dfb707300c34e4f1eb3b8a14f1 F Makefile.linux-gcc 06be33b2a9ad4f005a5f42b22c4a19dab3cbb5c7 F README 9c4e2d6706bdcc3efdd773ce752a8cdab4f90028 @@ -87,7 +87,7 @@ F src/vdbeapi.c 85bbe1d0243a89655433d60711b4bd71979b59cd F src/vdbeaux.c e3a815a88bbf68f17880f5bc077e1c35d14b9409 F src/vdbefifo.c 9efb94c8c3f4c979ebd0028219483f88e57584f5 F src/vdbemem.c fea0744936008831daa17cdc75056c3ca1469690 -F src/where.c 53a54c1434be9afa45db3558d9ae09450acea273 +F src/where.c a595744df3ce50c5d875bae06798054bbef1d7f9 F tclinstaller.tcl 046e3624671962dc50f0481d7c25b38ef803eb42 F test/all.test 7f0988442ab811dfa41793b5b550f5828ce316f3 F test/alter.test 9d6837a3d946b73df692b7cef2a7644d2e2f6bc6 @@ -217,6 +217,7 @@ F test/tester.tcl 98ecdc5723b3b2be5a8a5c3a7f38fa53031466ee F test/thread1.test 776c9e459b75ba905193b351926ac4019b049f35 F test/threadtest1.c 6029d9c5567db28e6dc908a0c63099c3ba6c383b F test/threadtest2.c 97a830d53c24c42290501fdfba4a6e5bdd34748b +F test/tkt1443.test c056bfdabb6c3144bca6f70ce52d32d25101c3b4 F test/trace.test 9fd28695c463b90c2d32c387a432e01eb26e8ccf F test/trans.test 10506dc30305cfb8c4098359f7f6f64786f69c5e F test/trigger1.test 152aed5a1fa90709fe171f2ca501a6b7f7901479 @@ -307,7 +308,7 @@ F www/tclsqlite.tcl ddcf912ea48695603c8ed7efb29f0812ef8d1b49 F www/vdbe.tcl 87a31ace769f20d3627a64fa1fade7fed47b90d0 F www/version3.tcl a99cf5f6d8bd4d5537584a2b342f0fb9fa601d8b F www/whentouse.tcl 97e2b5cd296f7d8057e11f44427dea8a4c2db513 -P 5b6dc12b7d25d999be5d282cd0b06e02e2bda765 -R 4c6f66bbc06ea3f6edd3c1720650c250 +P 0eaf430d9538ece1a3d1300db91f269577a5e028 +R 56daf0fd324c3c63c9831d6786cf42e7 U drh -Z db383a7aa31dfbfb4a753232e7f9eb89 +Z 3c070837de28d59d54c656780119322f diff --git a/manifest.uuid b/manifest.uuid index 6a0744d3d8..dbf5b65148 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -0eaf430d9538ece1a3d1300db91f269577a5e028 \ No newline at end of file +21740794ab81924442f358a6adbbe6d5590cf58d \ No newline at end of file diff --git a/src/where.c b/src/where.c index be35a110cf..1c507b3b23 100644 --- a/src/where.c +++ b/src/where.c @@ -16,7 +16,7 @@ ** so is applicable. Because this module is responsible for selecting ** indices, you might also think of this module as the "query optimizer". ** -** $Id: where.c,v 1.172 2005/09/16 02:38:11 drh Exp $ +** $Id: where.c,v 1.173 2005/09/17 13:07:13 drh Exp $ */ #include "sqliteInt.h" @@ -303,7 +303,8 @@ static void createMask(ExprMaskSet *pMaskSet, int iCursor){ ** translate the cursor numbers into bitmask values and OR all ** the bitmasks together. */ -static Bitmask exprListTableUsage(ExprMaskSet *, ExprList *); +static Bitmask exprListTableUsage(ExprMaskSet*, ExprList*); +static Bitmask exprSelectTableUsage(ExprMaskSet*, Select*); static Bitmask exprTableUsage(ExprMaskSet *pMaskSet, Expr *p){ Bitmask mask = 0; if( p==0 ) return 0; @@ -314,14 +315,7 @@ static Bitmask exprTableUsage(ExprMaskSet *pMaskSet, Expr *p){ mask = exprTableUsage(pMaskSet, p->pRight); mask |= exprTableUsage(pMaskSet, p->pLeft); mask |= exprListTableUsage(pMaskSet, p->pList); - if( p->pSelect ){ - Select *pS = p->pSelect; - mask |= exprListTableUsage(pMaskSet, pS->pEList); - mask |= exprListTableUsage(pMaskSet, pS->pGroupBy); - mask |= exprListTableUsage(pMaskSet, pS->pOrderBy); - mask |= exprTableUsage(pMaskSet, pS->pWhere); - mask |= exprTableUsage(pMaskSet, pS->pHaving); - } + mask |= exprSelectTableUsage(pMaskSet, p->pSelect); return mask; } static Bitmask exprListTableUsage(ExprMaskSet *pMaskSet, ExprList *pList){ @@ -334,6 +328,19 @@ static Bitmask exprListTableUsage(ExprMaskSet *pMaskSet, ExprList *pList){ } return mask; } +static Bitmask exprSelectTableUsage(ExprMaskSet *pMaskSet, Select *pS){ + Bitmask mask; + if( pS==0 ){ + mask = 0; + }else{ + mask = exprListTableUsage(pMaskSet, pS->pEList); + mask |= exprListTableUsage(pMaskSet, pS->pGroupBy); + mask |= exprListTableUsage(pMaskSet, pS->pOrderBy); + mask |= exprTableUsage(pMaskSet, pS->pWhere); + mask |= exprTableUsage(pMaskSet, pS->pHaving); + } + return mask; +} /* ** Return TRUE if the given operator is one of the operators that is @@ -542,7 +549,13 @@ static void exprAnalyze( if( sqlite3_malloc_failed ) return; prereqLeft = exprTableUsage(pMaskSet, pExpr->pLeft); - pTerm->prereqRight = exprTableUsage(pMaskSet, pExpr->pRight); + if( pExpr->op==TK_IN ){ + assert( pExpr->pRight==0 ); + pTerm->prereqRight = exprListTableUsage(pMaskSet, pExpr->pList) + | exprSelectTableUsage(pMaskSet, pExpr->pSelect); + }else{ + pTerm->prereqRight = exprTableUsage(pMaskSet, pExpr->pRight); + } pTerm->prereqAll = prereqAll = exprTableUsage(pMaskSet, pExpr); pTerm->leftCursor = -1; pTerm->iParent = -1; @@ -550,6 +563,7 @@ static void exprAnalyze( if( allowedOp(pExpr->op) && (pTerm->prereqRight & prereqLeft)==0 ){ Expr *pLeft = pExpr->pLeft; Expr *pRight = pExpr->pRight; + assert( prereqAll == (pTerm->prereqRight | prereqLeft) ); /* ticket 1433 */ if( pLeft->op==TK_COLUMN ){ pTerm->leftCursor = pLeft->iTable; pTerm->leftColumn = pLeft->iColumn; @@ -608,7 +622,13 @@ static void exprAnalyze( #ifndef SQLITE_OMIT_OR_OPTIMIZATION /* Attempt to convert OR-connected terms into an IN operator so that - ** they can make use of indices. + ** they can make use of indices. Example: + ** + ** x = expr1 OR expr2 = x OR x = expr3 + ** + ** is converted into + ** + ** x IN (expr1,expr2,expr3) */ else if( pExpr->op==TK_OR ){ int ok; diff --git a/test/tkt1443.test b/test/tkt1443.test new file mode 100644 index 0000000000..3f9bd3c155 --- /dev/null +++ b/test/tkt1443.test @@ -0,0 +1,170 @@ +# 2005 September 17 +# +# 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. +# +#*********************************************************************** +# This file implements regression tests for SQLite library. +# +# This file implements tests to verify that ticket #1433 has been +# fixed. +# +# The problem in ticket #1433 was that the dependencies on the right-hand +# side of an IN operator were not being checked correctly. So in an +# expression of the form: +# +# t1.x IN (1,t2.b,3) +# +# the optimizer was missing the fact that the right-hand side of the IN +# depended on table t2. It was checking dependencies based on the +# Expr.pRight field rather than Expr.pList and Expr.pSelect. +# +# Such a bug could be verifed using a less elaborate test case. But +# this test case (from the original bug poster) exercises so many different +# parts of the system all at once, that it seemed like a good one to +# include in the test suite. +# +# $Id: tkt1443.test,v 1.1 2005/09/17 13:07:13 drh Exp $ + +set testdir [file dirname $argv0] +source $testdir/tester.tcl + + +# Construct the sample database. +# +do_test tkt1433-1.0 { + sqlite3 db :memory: + execsql { + CREATE TABLE Items( + itemId integer primary key, + item str unique + ); + INSERT INTO "Items" VALUES(0, 'ALL'); + INSERT INTO "Items" VALUES(1, 'double:source'); + INSERT INTO "Items" VALUES(2, 'double'); + INSERT INTO "Items" VALUES(3, 'double:runtime'); + INSERT INTO "Items" VALUES(4, '.*:runtime'); + + CREATE TABLE Labels( + labelId INTEGER PRIMARY KEY, + label STR UNIQUE + ); + INSERT INTO "Labels" VALUES(0, 'ALL'); + INSERT INTO "Labels" VALUES(1, 'localhost@rpl:linux'); + INSERT INTO "Labels" VALUES(2, 'localhost@rpl:branch'); + + CREATE TABLE LabelMap( + itemId INTEGER, + labelId INTEGER, + branchId integer + ); + INSERT INTO "LabelMap" VALUES(1, 1, 1); + INSERT INTO "LabelMap" VALUES(2, 1, 1); + INSERT INTO "LabelMap" VALUES(3, 1, 1); + INSERT INTO "LabelMap" VALUES(1, 2, 2); + INSERT INTO "LabelMap" VALUES(2, 2, 3); + INSERT INTO "LabelMap" VALUES(3, 2, 3); + + CREATE TABLE Users ( + userId INTEGER PRIMARY KEY, + user STRING UNIQUE, + salt BINARY, + password STRING + ); + INSERT INTO "Users" VALUES(1, 'test', 'Šæ$d', + '43ba0f45014306bd6df529551ffdb3df'); + INSERT INTO "Users" VALUES(2, 'limited', 'ªš>S', + 'cf07c8348fdf675cc1f7696b7d45191b'); + CREATE TABLE UserGroups ( + userGroupId INTEGER PRIMARY KEY, + userGroup STRING UNIQUE + ); + INSERT INTO "UserGroups" VALUES(1, 'test'); + INSERT INTO "UserGroups" VALUES(2, 'limited'); + + CREATE TABLE UserGroupMembers ( + userGroupId INTEGER, + userId INTEGER + ); + INSERT INTO "UserGroupMembers" VALUES(1, 1); + INSERT INTO "UserGroupMembers" VALUES(2, 2); + + CREATE TABLE Permissions ( + userGroupId INTEGER, + labelId INTEGER NOT NULL, + itemId INTEGER NOT NULL, + write INTEGER, + capped INTEGER, + admin INTEGER + ); + INSERT INTO "Permissions" VALUES(1, 0, 0, 1, 0, 1); + INSERT INTO "Permissions" VALUES(2, 2, 4, 0, 0, 0); + } +} {} + +# Run the query with an index +# +do_test tkt1443-1.1 { + execsql { + select distinct + Items.Item as trove, UP.pattern as pattern + from + ( select + Permissions.labelId as labelId, + PerItems.item as pattern + from + Users, UserGroupMembers, Permissions + left outer join Items as PerItems + on Permissions.itemId = PerItems.itemId + where + Users.user = 'limited' + and Users.userId = UserGroupMembers.userId + and UserGroupMembers.userGroupId = Permissions.userGroupId + ) as UP join LabelMap on ( UP.labelId = 0 or + UP.labelId = LabelMap.labelId ), + Labels, Items + where + Labels.label = 'localhost@rpl:branch' + and Labels.labelId = LabelMap.labelId + and LabelMap.itemId = Items.itemId + ORDER BY +trove, +pattern + } +} {double .*:runtime double:runtime .*:runtime double:source .*:runtime} + +# Create an index and rerun the query. +# Verify that the results are the same +# +do_test tkt1443-1.2 { + execsql { + CREATE UNIQUE INDEX PermissionsIdx + ON Permissions(userGroupId, labelId, itemId); + select distinct + Items.Item as trove, UP.pattern as pattern + from + ( select + Permissions.labelId as labelId, + PerItems.item as pattern + from + Users, UserGroupMembers, Permissions + left outer join Items as PerItems + on Permissions.itemId = PerItems.itemId + where + Users.user = 'limited' + and Users.userId = UserGroupMembers.userId + and UserGroupMembers.userGroupId = Permissions.userGroupId + ) as UP join LabelMap on ( UP.labelId = 0 or + UP.labelId = LabelMap.labelId ), + Labels, Items + where + Labels.label = 'localhost@rpl:branch' + and Labels.labelId = LabelMap.labelId + and LabelMap.itemId = Items.itemId + ORDER BY +trove, +pattern + } +} {double .*:runtime double:runtime .*:runtime double:source .*:runtime} + +finish_test