Enhance the query planner to exploit transitivity of join constraints.

FossilOrigin-Name: 38852f158ab20bb4d7b264af987ec1538052bec3
This commit is contained in:
drh 2013-01-17 17:20:49 +00:00
commit f218ee2dd4
6 changed files with 322 additions and 79 deletions

View File

@ -1,5 +1,5 @@
C Improved\serror\smessages\son\sthe\sRTREE\svirtual\stable.\s\sMake\sthe\s"fs"\svirtual\ntable\sused\sfor\stesting\savailable\son\swindows.
D 2013-01-17T17:05:28.012
C Enhance\sthe\squery\splanner\sto\sexploit\stransitivity\sof\sjoin\sconstraints.
D 2013-01-17T17:20:49.316
F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f
F Makefile.in a48faa9e7dd7d556d84f5456eabe5825dd8a6282
F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23
@ -179,7 +179,7 @@ F src/shell.c 11c9611580bb2ffce3a232f31f7f8cc310df0843
F src/sqlite.h.in 39cc33bb08897c748fe3383c29ccf56585704177
F src/sqlite3.rc fea433eb0a59f4c9393c8e6d76a6e2596b1fe0c0
F src/sqlite3ext.h 6904f4aadf976f95241311fbffb00823075d9477
F src/sqliteInt.h e998703742455b2241731424c6ec142fd8d0258f
F src/sqliteInt.h fb4109b7a77d985a39bbd04f1fbc49c940d4e410
F src/sqliteLimit.h 164b0e6749d31e0daa1a4589a169d31c0dec7b3d
F src/status.c bedc37ec1a6bb9399944024d63f4c769971955a9
F src/table.c 2cd62736f845d82200acfa1287e33feb3c15d62e
@ -252,7 +252,7 @@ F src/vtab.c b05e5f1f4902461ba9f5fc49bb7eb7c3a0741a83
F src/wal.c f5c7b5027d0ed0e9bc9afeb4a3a8dfea762ec7d2
F src/wal.h 29c197540b19044e6cd73487017e5e47a1d3dac6
F src/walker.c 3d75ba73de15e0f8cd0737643badbeb0e002f07b
F src/where.c d48a57d8afd97c51f1b772ebd72431a43a0e48b3
F src/where.c 374a6c8190f863b3c69780b441d799e8a6b9e21b
F test/8_3_names.test 631ea964a3edb091cf73c3b540f6bcfdb36ce823
F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2
F test/aggnested.test 45c0201e28045ad38a530b5a144b73cd4aa2cfd6
@ -285,7 +285,7 @@ F test/auth.test 304e82f31592820d3bde26ab6b75deaa123e1a6f
F test/auth2.test a2a371aa6df15f8b0c8109b33d3d7f0f73e4c9aa
F test/auth3.test a4755e6a2a2fea547ffe63c874eb569e60a28eb5
F test/autoinc.test bd30d372d00045252f6c2e41b5f41455e1975acf
F test/autoindex1.test 058d0b331ae6840a61bbee910d8cbae27bfd5991
F test/autoindex1.test f88146c4c889ea0afbb620e49d83b5fbf5ee4d06
F test/autovacuum.test 9f22a7733f39c56ef6a5665d10145ac25d8cb574
F test/autovacuum_ioerr2.test 8a367b224183ad801e0e24dcb7d1501f45f244b4
F test/avtrans.test 0252654f4295ddda3b2cce0e894812259e655a85
@ -896,6 +896,7 @@ F test/trace2.test c1dc104a8d11a347c870cfea6235e3fc6f6cb06d
F test/trans.test 6e1b4c6a42dba31bd65f8fa5e61a2708e08ddde6
F test/trans2.test d5337e61de45e66b1fcbf9db833fa8c82e624b22
F test/trans3.test 373ac5183cc56be69f48ae44090e7f672939f732
F test/transitive1.test d04aa9023e425d6f2d4aa61dd81ee9e102f89062
F test/trigger1.test 30f343f91586765874a28ad539c06f5a5f049931
F test/trigger2.test 834187beafd1db383af0c659cfa49b0576832816
F test/trigger3.test d2c60d8be271c355d61727411e753181e877230a
@ -1033,7 +1034,7 @@ F tool/vdbe-compress.tcl f12c884766bd14277f4fcedcae07078011717381
F tool/warnings-clang.sh f6aa929dc20ef1f856af04a730772f59283631d4
F tool/warnings.sh fbc018d67fd7395f440c28f33ef0f94420226381
F tool/win/sqlite.vsix 97894c2790eda7b5bce3cc79cb2a8ec2fde9b3ac
P 6195ebd83323eaad92a0aa095cce1094bf8e2ba6 652233d646236d3fbca629813b20d075f00f3ed6
R 6de5433403d98c9088f8c6d2808c6cc6
P c0b90d75a86b01f7fafec755cbe046c14d725341 593d67c8b0908daf7a70b2a310ed85515d384cbf
R 19cb0000f7ea18bbcd69f74a26ccdcaa
U drh
Z 0204ef4d219a8c63e57ef7237c96ae79
Z bcbd2dcec0eed1962ecdbd3953e8a1f1

View File

@ -1 +1 @@
c0b90d75a86b01f7fafec755cbe046c14d725341
38852f158ab20bb4d7b264af987ec1538052bec3

View File

@ -575,6 +575,11 @@ struct BusyHandler {
*/
#define ArraySize(X) ((int)(sizeof(X)/sizeof(X[0])))
/*
** Determine if the argument is a power of two
*/
#define IsPowerOfTwo(X) (((X)&((X)-1))==0)
/*
** The following value as a destructor means to use sqlite3DbFree().
** The sqlite3DbFree() routine requires two parameters instead of the
@ -973,6 +978,7 @@ struct sqlite3 {
#define SQLITE_CoverIdxScan 0x0040 /* Covering index scans */
#define SQLITE_OrderByIdxJoin 0x0080 /* ORDER BY of joins via index */
#define SQLITE_SubqCoroutine 0x0100 /* Evaluate subqueries as coroutines */
#define SQLITE_Transitive 0x0200 /* Transitive constraints */
#define SQLITE_AllOpts 0xffff /* All optimizations */
/*

View File

@ -98,8 +98,8 @@ struct WhereTerm {
int leftCursor; /* Cursor number of X in "X <op> <expr>" */
union {
int leftColumn; /* Column number of X in "X <op> <expr>" */
WhereOrInfo *pOrInfo; /* Extra information if eOperator==WO_OR */
WhereAndInfo *pAndInfo; /* Extra information if eOperator==WO_AND */
WhereOrInfo *pOrInfo; /* Extra information if (eOperator & WO_OR)!=0 */
WhereAndInfo *pAndInfo; /* Extra information if (eOperator& WO_AND)!=0 */
} u;
u16 eOperator; /* A WO_xx value describing <op> */
u8 wtFlags; /* TERM_xxx bit flags. See below */
@ -227,6 +227,7 @@ struct WhereCost {
#define WO_ISNULL 0x080
#define WO_OR 0x100 /* Two or more OR-connected terms */
#define WO_AND 0x200 /* Two or more AND-connected terms */
#define WO_EQUIV 0x400 /* Of the form A==B, both columns */
#define WO_NOOP 0x800 /* This term does not restrict search space */
#define WO_ALL 0xfff /* Mask of all possible WO_* values */
@ -629,6 +630,24 @@ static u16 operatorMask(int op){
** where X is a reference to the iColumn of table iCur and <op> is one of
** the WO_xx operator codes specified by the op parameter.
** Return a pointer to the term. Return 0 if not found.
**
** The term returned might by Y=<expr> if there is another constraint in
** the WHERE clause that specifies that X=Y. Any such constraints will be
** identified by the WO_EQUIV bit in the pTerm->eOperator field. The
** aEquiv[] array holds X and all its equivalents, with each SQL variable
** taking up two slots in aEquiv[]. The first slot is for the cursor number
** and the second is for the column number. There are 22 slots in aEquiv[]
** so that means we can look for X plus up to 10 other equivalent values.
** Hence a search for X will return <expr> if X=A1 and A1=A2 and A2=A3
** and ... and A9=A10 and A10=<expr>.
**
** If there are multiple terms in the WHERE clause of the form "X <op> <expr>"
** then try for the one with no dependencies on <expr> - in other words where
** <expr> is a constant expression of some kind. Only return entries of
** the form "X <op> Y" where Y is a column in another table if no terms of
** the form "X <op> <const-expr>" exist. Other than this priority, if there
** are two or more terms that match, then the choice of which term to return
** is arbitrary.
*/
static WhereTerm *findTerm(
WhereClause *pWC, /* The WHERE clause to be searched */
@ -638,45 +657,81 @@ static WhereTerm *findTerm(
u32 op, /* Mask of WO_xx values describing operator */
Index *pIdx /* Must be compatible with this index, if not NULL */
){
WhereTerm *pTerm;
int k;
WhereTerm *pTerm; /* Term being examined as possible result */
WhereTerm *pResult = 0; /* The answer to return */
WhereClause *pWCOrig = pWC; /* Original pWC value */
int j, k; /* Loop counters */
Expr *pX; /* Pointer to an expression */
Parse *pParse; /* Parsing context */
int iOrigCol = iColumn; /* Original value of iColumn */
int nEquiv = 2; /* Number of entires in aEquiv[] */
int iEquiv = 2; /* Number of entries of aEquiv[] processed so far */
int aEquiv[22]; /* iCur,iColumn and up to 10 other equivalents */
assert( iCur>=0 );
op &= WO_ALL;
for(; pWC; pWC=pWC->pOuter){
for(pTerm=pWC->a, k=pWC->nTerm; k; k--, pTerm++){
if( pTerm->leftCursor==iCur
&& (pTerm->prereqRight & notReady)==0
&& pTerm->u.leftColumn==iColumn
&& (pTerm->eOperator & op)!=0
){
if( iColumn>=0 && pIdx && pTerm->eOperator!=WO_ISNULL ){
Expr *pX = pTerm->pExpr;
CollSeq *pColl;
char idxaff;
int j;
Parse *pParse = pWC->pParse;
idxaff = pIdx->pTable->aCol[iColumn].affinity;
if( !sqlite3IndexAffinityOk(pX, idxaff) ) continue;
/* Figure out the collation sequence required from an index for
** it to be useful for optimising expression pX. Store this
** value in variable pColl.
*/
assert(pX->pLeft);
pColl = sqlite3BinaryCompareCollSeq(pParse, pX->pLeft, pX->pRight);
if( pColl==0 ) pColl = pParse->db->pDfltColl;
for(j=0; pIdx->aiColumn[j]!=iColumn; j++){
if( NEVER(j>=pIdx->nColumn) ) return 0;
aEquiv[0] = iCur;
aEquiv[1] = iColumn;
for(;;){
for(pWC=pWCOrig; pWC; pWC=pWC->pOuter){
for(pTerm=pWC->a, k=pWC->nTerm; k; k--, pTerm++){
if( pTerm->leftCursor==iCur
&& pTerm->u.leftColumn==iColumn
){
if( (pTerm->prereqRight & notReady)==0
&& (pTerm->eOperator & op & WO_ALL)!=0
){
if( iOrigCol>=0 && pIdx && (pTerm->eOperator & WO_ISNULL)==0 ){
CollSeq *pColl;
char idxaff;
pX = pTerm->pExpr;
pParse = pWC->pParse;
idxaff = pIdx->pTable->aCol[iOrigCol].affinity;
if( !sqlite3IndexAffinityOk(pX, idxaff) ){
continue;
}
/* Figure out the collation sequence required from an index for
** it to be useful for optimising expression pX. Store this
** value in variable pColl.
*/
assert(pX->pLeft);
pColl = sqlite3BinaryCompareCollSeq(pParse,pX->pLeft,pX->pRight);
if( pColl==0 ) pColl = pParse->db->pDfltColl;
for(j=0; pIdx->aiColumn[j]!=iOrigCol; j++){
if( NEVER(j>=pIdx->nColumn) ) return 0;
}
if( sqlite3StrICmp(pColl->zName, pIdx->azColl[j]) ){
continue;
}
}
pResult = pTerm;
if( pTerm->prereqRight==0 ) goto findTerm_success;
}
if( (pTerm->eOperator & WO_EQUIV)!=0
&& nEquiv<ArraySize(aEquiv)
){
pX = sqlite3ExprSkipCollate(pTerm->pExpr->pRight);
assert( pX->op==TK_COLUMN );
for(j=0; j<nEquiv; j+=2){
if( aEquiv[j]==pX->iTable && aEquiv[j+1]==pX->iColumn ) break;
}
if( j==nEquiv ){
aEquiv[j] = pX->iTable;
aEquiv[j+1] = pX->iColumn;
nEquiv += 2;
}
}
if( sqlite3StrICmp(pColl->zName, pIdx->azColl[j]) ) continue;
}
return pTerm;
}
}
if( iEquiv>=nEquiv ) break;
iCur = aEquiv[iEquiv++];
iColumn = aEquiv[iEquiv++];
}
return 0;
findTerm_success:
return pResult;
}
/* Forward reference */
@ -954,7 +1009,6 @@ static void exprAnalyzeOrTerm(
for(i=pOrWc->nTerm-1, pOrTerm=pOrWc->a; i>=0 && indexable; i--, pOrTerm++){
if( (pOrTerm->eOperator & WO_SINGLE)==0 ){
WhereAndInfo *pAndInfo;
assert( pOrTerm->eOperator==0 );
assert( (pOrTerm->wtFlags & (TERM_ANDINFO|TERM_ORINFO))==0 );
chngToIN = 0;
pAndInfo = sqlite3DbMallocRaw(db, sizeof(*pAndInfo));
@ -993,7 +1047,7 @@ static void exprAnalyzeOrTerm(
b |= getMask(pMaskSet, pOther->leftCursor);
}
indexable &= b;
if( pOrTerm->eOperator!=WO_EQ ){
if( (pOrTerm->eOperator & WO_EQ)==0 ){
chngToIN = 0;
}else{
chngToIN &= b;
@ -1044,7 +1098,7 @@ static void exprAnalyzeOrTerm(
for(j=0; j<2 && !okToChngToIN; j++){
pOrTerm = pOrWc->a;
for(i=pOrWc->nTerm-1; i>=0; i--, pOrTerm++){
assert( pOrTerm->eOperator==WO_EQ );
assert( pOrTerm->eOperator & WO_EQ );
pOrTerm->wtFlags &= ~TERM_OR_OK;
if( pOrTerm->leftCursor==iCursor ){
/* This is the 2-bit case and we are on the second iteration and
@ -1070,7 +1124,7 @@ static void exprAnalyzeOrTerm(
/* No candidate table+column was found. This can only occur
** on the second iteration */
assert( j==1 );
assert( (chngToIN&(chngToIN-1))==0 );
assert( IsPowerOfTwo(chngToIN) );
assert( chngToIN==getMask(pMaskSet, iCursor) );
break;
}
@ -1080,7 +1134,7 @@ static void exprAnalyzeOrTerm(
** table and column is common to every term in the OR clause */
okToChngToIN = 1;
for(; i>=0 && okToChngToIN; i--, pOrTerm++){
assert( pOrTerm->eOperator==WO_EQ );
assert( pOrTerm->eOperator & WO_EQ );
if( pOrTerm->leftCursor!=iCursor ){
pOrTerm->wtFlags &= ~TERM_OR_OK;
}else if( pOrTerm->u.leftColumn!=iColumn ){
@ -1116,7 +1170,7 @@ static void exprAnalyzeOrTerm(
for(i=pOrWc->nTerm-1, pOrTerm=pOrWc->a; i>=0; i--, pOrTerm++){
if( (pOrTerm->wtFlags & TERM_OR_OK)==0 ) continue;
assert( pOrTerm->eOperator==WO_EQ );
assert( pOrTerm->eOperator & WO_EQ );
assert( pOrTerm->leftCursor==iCursor );
assert( pOrTerm->u.leftColumn==iColumn );
pDup = sqlite3ExprDup(db, pOrTerm->pExpr->pRight, 0);
@ -1146,7 +1200,6 @@ static void exprAnalyzeOrTerm(
}
#endif /* !SQLITE_OMIT_OR_OPTIMIZATION && !SQLITE_OMIT_SUBQUERY */
/*
** The input to this routine is an WhereTerm structure with only the
** "pExpr" field filled in. The job of this routine is to analyze the
@ -1215,17 +1268,19 @@ static void exprAnalyze(
pTerm->leftCursor = -1;
pTerm->iParent = -1;
pTerm->eOperator = 0;
if( allowedOp(op) && (pTerm->prereqRight & prereqLeft)==0 ){
if( allowedOp(op) ){
Expr *pLeft = sqlite3ExprSkipCollate(pExpr->pLeft);
Expr *pRight = sqlite3ExprSkipCollate(pExpr->pRight);
u16 opMask = (pTerm->prereqRight & prereqLeft)==0 ? WO_ALL : WO_EQUIV;
if( pLeft->op==TK_COLUMN ){
pTerm->leftCursor = pLeft->iTable;
pTerm->u.leftColumn = pLeft->iColumn;
pTerm->eOperator = operatorMask(op);
pTerm->eOperator = operatorMask(op) & opMask;
}
if( pRight && pRight->op==TK_COLUMN ){
WhereTerm *pNew;
Expr *pDup;
u16 eExtraOp = 0; /* Extra bits for pNew->eOperator */
if( pTerm->leftCursor>=0 ){
int idxNew;
pDup = sqlite3ExprDup(db, pExpr, 0);
@ -1240,6 +1295,13 @@ static void exprAnalyze(
pTerm = &pWC->a[idxTerm];
pTerm->nChild = 1;
pTerm->wtFlags |= TERM_COPIED;
if( pExpr->op==TK_EQ
&& !ExprHasProperty(pExpr, EP_FromJoin)
&& OptimizationEnabled(db, SQLITE_Transitive)
){
pTerm->eOperator |= WO_EQUIV;
eExtraOp = WO_EQUIV;
}
}else{
pDup = pExpr;
pNew = pTerm;
@ -1251,7 +1313,7 @@ static void exprAnalyze(
testcase( (prereqLeft | extraRight) != prereqLeft );
pNew->prereqRight = prereqLeft | extraRight;
pNew->prereqAll = prereqAll;
pNew->eOperator = operatorMask(pDup->op);
pNew->eOperator = (operatorMask(pDup->op) + eExtraOp) & opMask;
}
}
@ -1710,7 +1772,7 @@ static void bestOrClauseIndex(WhereBestIdx *p){
/* Search the WHERE clause terms for a usable WO_OR term. */
for(pTerm=pWC->a; pTerm<pWCEnd; pTerm++){
if( pTerm->eOperator==WO_OR
if( (pTerm->eOperator & WO_OR)!=0
&& ((pTerm->prereqAll & ~maskSrc) & p->notReady)==0
&& (pTerm->u.pOrInfo->indexable & maskSrc)!=0
){
@ -1731,7 +1793,7 @@ static void bestOrClauseIndex(WhereBestIdx *p){
WHERETRACE(("... Multi-index OR testing for term %d of %d....\n",
(pOrTerm - pOrWC->a), (pTerm - pWC->a)
));
if( pOrTerm->eOperator==WO_AND ){
if( (pOrTerm->eOperator& WO_AND)!=0 ){
sBOI.pWC = &pOrTerm->u.pAndInfo->wc;
bestIndex(&sBOI);
}else if( pOrTerm->leftCursor==iCur ){
@ -1792,7 +1854,7 @@ static int termCanDriveIndex(
){
char aff;
if( pTerm->leftCursor!=pSrc->iCursor ) return 0;
if( pTerm->eOperator!=WO_EQ ) return 0;
if( (pTerm->eOperator & WO_EQ)==0 ) return 0;
if( (pTerm->prereqRight & notReady)!=0 ) return 0;
aff = pSrc->pTab->aCol[pTerm->u.leftColumn].affinity;
if( !sqlite3IndexAffinityOk(pTerm->pExpr, aff) ) return 0;
@ -2054,9 +2116,9 @@ static sqlite3_index_info *allocateIndexInfo(WhereBestIdx *p){
** to this virtual table */
for(i=nTerm=0, pTerm=pWC->a; i<pWC->nTerm; i++, pTerm++){
if( pTerm->leftCursor != pSrc->iCursor ) continue;
assert( (pTerm->eOperator&(pTerm->eOperator-1))==0 );
testcase( pTerm->eOperator==WO_IN );
testcase( pTerm->eOperator==WO_ISNULL );
assert( IsPowerOfTwo(pTerm->eOperator & ~WO_EQUIV) );
testcase( pTerm->eOperator & WO_IN );
testcase( pTerm->eOperator & WO_ISNULL );
if( pTerm->eOperator & (WO_ISNULL) ) continue;
if( pTerm->wtFlags & TERM_VNULL ) continue;
nTerm++;
@ -2107,14 +2169,14 @@ static sqlite3_index_info *allocateIndexInfo(WhereBestIdx *p){
for(i=j=0, pTerm=pWC->a; i<pWC->nTerm; i++, pTerm++){
u8 op;
if( pTerm->leftCursor != pSrc->iCursor ) continue;
assert( (pTerm->eOperator&(pTerm->eOperator-1))==0 );
testcase( pTerm->eOperator==WO_IN );
testcase( pTerm->eOperator==WO_ISNULL );
assert( IsPowerOfTwo(pTerm->eOperator & ~WO_EQUIV) );
testcase( pTerm->eOperator & WO_IN );
testcase( pTerm->eOperator & WO_ISNULL );
if( pTerm->eOperator & (WO_ISNULL) ) continue;
if( pTerm->wtFlags & TERM_VNULL ) continue;
pIdxCons[j].iColumn = pTerm->u.leftColumn;
pIdxCons[j].iTermOffset = i;
op = (u8)pTerm->eOperator;
op = (u8)pTerm->eOperator & WO_ALL;
if( op==WO_IN ) op = WO_EQ;
pIdxCons[j].op = op;
/* The direct assignment in the previous line is possible only because
@ -2284,7 +2346,7 @@ static void bestVirtualIndex(WhereBestIdx *p){
j = pIdxCons->iTermOffset;
pTerm = &pWC->a[j];
if( (pTerm->prereqRight&p->notReady)==0
&& (bAllowIN || pTerm->eOperator!=WO_IN)
&& (bAllowIN || (pTerm->eOperator & WO_IN)==0)
){
pIdxCons->usable = 1;
}else{
@ -2316,7 +2378,7 @@ static void bestVirtualIndex(WhereBestIdx *p){
j = pIdxCons->iTermOffset;
pTerm = &pWC->a[j];
p->cost.used |= pTerm->prereqRight;
if( pTerm->eOperator==WO_IN && pUsage[i].omit==0 ){
if( (pTerm->eOperator & WO_IN)!=0 && pUsage[i].omit==0 ){
/* Do not attempt to use an IN constraint if the virtual table
** says that the equivalent EQ constraint cannot be safely omitted.
** If we do attempt to use such a constraint, some rows might be
@ -2622,24 +2684,24 @@ static int whereRangeScanEst(
if( pLower ){
Expr *pExpr = pLower->pExpr->pRight;
rc = valueFromExpr(pParse, pExpr, aff, &pRangeVal);
assert( pLower->eOperator==WO_GT || pLower->eOperator==WO_GE );
assert( (pLower->eOperator & (WO_GT|WO_GE))!=0 );
if( rc==SQLITE_OK
&& whereKeyStats(pParse, p, pRangeVal, 0, a)==SQLITE_OK
){
iLower = a[0];
if( pLower->eOperator==WO_GT ) iLower += a[1];
if( (pLower->eOperator & WO_GT)!=0 ) iLower += a[1];
}
sqlite3ValueFree(pRangeVal);
}
if( rc==SQLITE_OK && pUpper ){
Expr *pExpr = pUpper->pExpr->pRight;
rc = valueFromExpr(pParse, pExpr, aff, &pRangeVal);
assert( pUpper->eOperator==WO_LT || pUpper->eOperator==WO_LE );
assert( (pUpper->eOperator & (WO_LT|WO_LE))!=0 );
if( rc==SQLITE_OK
&& whereKeyStats(pParse, p, pRangeVal, 1, a)==SQLITE_OK
){
iUpper = a[0];
if( pUpper->eOperator==WO_LE ) iUpper += a[1];
if( (pUpper->eOperator & WO_LE)!=0 ) iUpper += a[1];
}
sqlite3ValueFree(pRangeVal);
}
@ -2947,12 +3009,12 @@ static int isSortingIndex(
WO_EQ|WO_ISNULL|WO_IN, pIdx);
if( pConstraint==0 ){
isEq = 0;
}else if( pConstraint->eOperator==WO_IN ){
}else if( (pConstraint->eOperator & WO_IN)!=0 ){
/* Constraints of the form: "X IN ..." cannot be used with an ORDER BY
** because we do not know in what order the values on the RHS of the IN
** operator will occur. */
break;
}else if( pConstraint->eOperator==WO_ISNULL ){
}else if( (pConstraint->eOperator & WO_ISNULL)!=0 ){
uniqueNotNull = 0;
isEq = 1; /* "X IS NULL" means X has only a single value */
}else if( pConstraint->prereqRight==0 ){
@ -3365,12 +3427,13 @@ static void bestBtreeIndex(WhereBestIdx *p){
&& pFirstTerm!=0 && aiRowEst[1]>1 ){
assert( (pFirstTerm->eOperator & (WO_EQ|WO_ISNULL|WO_IN))!=0 );
if( pFirstTerm->eOperator & (WO_EQ|WO_ISNULL) ){
testcase( pFirstTerm->eOperator==WO_EQ );
testcase( pFirstTerm->eOperator==WO_ISNULL );
testcase( pFirstTerm->eOperator & WO_EQ );
testcase( pFirstTerm->eOperator & WO_EQUIV );
testcase( pFirstTerm->eOperator & WO_ISNULL );
whereEqualScanEst(pParse, pProbe, pFirstTerm->pExpr->pRight,
&pc.plan.nRow);
}else if( bInEst==0 ){
assert( pFirstTerm->eOperator==WO_IN );
assert( pFirstTerm->eOperator & WO_IN );
whereInScanEst(pParse, pProbe, pFirstTerm->pExpr->x.pList,
&pc.plan.nRow);
}
@ -3517,7 +3580,7 @@ static void bestBtreeIndex(WhereBestIdx *p){
** selective in practice, on average. */
pc.plan.nRow /= 3;
}
}else if( pTerm->eOperator!=WO_NOOP ){
}else if( (pTerm->eOperator & WO_NOOP)==0 ){
/* Any other expression lowers the output row count by half */
pc.plan.nRow /= 2;
}
@ -4153,7 +4216,6 @@ static Bitmask codeOneLoopStart(
pTerm = findTerm(pWC, iCur, -1, notReady, WO_EQ|WO_IN, 0);
assert( pTerm!=0 );
assert( pTerm->pExpr!=0 );
assert( pTerm->leftCursor==iCur );
assert( omitTable==0 );
testcase( pTerm->wtFlags & TERM_VIRTUAL ); /* EV: R-30575-11662 */
iRowidReg = codeEqualityTerm(pParse, pTerm, pLevel, iReleaseReg);
@ -4544,7 +4606,7 @@ static Bitmask codeOneLoopStart(
pTerm = pLevel->plan.u.pTerm;
assert( pTerm!=0 );
assert( pTerm->eOperator==WO_OR );
assert( pTerm->eOperator & WO_OR );
assert( (pTerm->wtFlags & TERM_ORINFO)!=0 );
pOrWc = &pTerm->u.pOrInfo->wc;
pLevel->op = OP_Return;
@ -4617,7 +4679,7 @@ static Bitmask codeOneLoopStart(
for(ii=0; ii<pOrWc->nTerm; ii++){
WhereTerm *pOrTerm = &pOrWc->a[ii];
if( pOrTerm->leftCursor==iCur || pOrTerm->eOperator==WO_AND ){
if( pOrTerm->leftCursor==iCur || (pOrTerm->eOperator & WO_AND)!=0 ){
WhereInfo *pSubWInfo; /* Info for single OR-term scan */
Expr *pOrExpr = pOrTerm->pExpr;
if( pAndExpr ){

View File

@ -257,5 +257,129 @@ do_execsql_test autoindex1-700 {
0 0 0 {USE TEMP B-TREE FOR ORDER BY}
}
# The following checks a performance issue reported on the sqlite-dev
# mailing list on 2013-01-10
#
do_execsql_test autoindex1-800 {
CREATE TABLE accounts(
_id INTEGER PRIMARY KEY AUTOINCREMENT,
account_name TEXT,
account_type TEXT,
data_set TEXT
);
CREATE TABLE data(
_id INTEGER PRIMARY KEY AUTOINCREMENT,
package_id INTEGER REFERENCES package(_id),
mimetype_id INTEGER REFERENCES mimetype(_id) NOT NULL,
raw_contact_id INTEGER REFERENCES raw_contacts(_id) NOT NULL,
is_read_only INTEGER NOT NULL DEFAULT 0,
is_primary INTEGER NOT NULL DEFAULT 0,
is_super_primary INTEGER NOT NULL DEFAULT 0,
data_version INTEGER NOT NULL DEFAULT 0,
data1 TEXT,
data2 TEXT,
data3 TEXT,
data4 TEXT,
data5 TEXT,
data6 TEXT,
data7 TEXT,
data8 TEXT,
data9 TEXT,
data10 TEXT,
data11 TEXT,
data12 TEXT,
data13 TEXT,
data14 TEXT,
data15 TEXT,
data_sync1 TEXT,
data_sync2 TEXT,
data_sync3 TEXT,
data_sync4 TEXT
);
CREATE TABLE mimetypes(
_id INTEGER PRIMARY KEY AUTOINCREMENT,
mimetype TEXT NOT NULL
);
CREATE TABLE raw_contacts(
_id INTEGER PRIMARY KEY AUTOINCREMENT,
account_id INTEGER REFERENCES accounts(_id),
sourceid TEXT,
raw_contact_is_read_only INTEGER NOT NULL DEFAULT 0,
version INTEGER NOT NULL DEFAULT 1,
dirty INTEGER NOT NULL DEFAULT 0,
deleted INTEGER NOT NULL DEFAULT 0,
contact_id INTEGER REFERENCES contacts(_id),
aggregation_mode INTEGER NOT NULL DEFAULT 0,
aggregation_needed INTEGER NOT NULL DEFAULT 1,
custom_ringtone TEXT,
send_to_voicemail INTEGER NOT NULL DEFAULT 0,
times_contacted INTEGER NOT NULL DEFAULT 0,
last_time_contacted INTEGER,
starred INTEGER NOT NULL DEFAULT 0,
display_name TEXT,
display_name_alt TEXT,
display_name_source INTEGER NOT NULL DEFAULT 0,
phonetic_name TEXT,
phonetic_name_style TEXT,
sort_key TEXT,
sort_key_alt TEXT,
name_verified INTEGER NOT NULL DEFAULT 0,
sync1 TEXT,
sync2 TEXT,
sync3 TEXT,
sync4 TEXT,
sync_uid TEXT,
sync_version INTEGER NOT NULL DEFAULT 1,
has_calendar_event INTEGER NOT NULL DEFAULT 0,
modified_time INTEGER,
is_restricted INTEGER DEFAULT 0,
yp_source TEXT,
method_selected INTEGER DEFAULT 0,
custom_vibration_type INTEGER DEFAULT 0,
custom_ringtone_path TEXT,
message_notification TEXT,
message_notification_path TEXT
);
CREATE INDEX data_mimetype_data1_index ON data (mimetype_id,data1);
CREATE INDEX data_raw_contact_id ON data (raw_contact_id);
CREATE UNIQUE INDEX mime_type ON mimetypes (mimetype);
CREATE INDEX raw_contact_sort_key1_index ON raw_contacts (sort_key);
CREATE INDEX raw_contact_sort_key2_index ON raw_contacts (sort_key_alt);
CREATE INDEX raw_contacts_contact_id_index ON raw_contacts (contact_id);
CREATE INDEX raw_contacts_source_id_account_id_index
ON raw_contacts (sourceid, account_id);
ANALYZE sqlite_master;
INSERT INTO sqlite_stat1
VALUES('raw_contacts','raw_contact_sort_key2_index','1600 4');
INSERT INTO sqlite_stat1
VALUES('raw_contacts','raw_contact_sort_key1_index','1600 4');
INSERT INTO sqlite_stat1
VALUES('raw_contacts','raw_contacts_source_id_account_id_index',
'1600 1600 1600');
INSERT INTO sqlite_stat1
VALUES('raw_contacts','raw_contacts_contact_id_index','1600 1');
INSERT INTO sqlite_stat1 VALUES('mimetypes','mime_type','12 1');
INSERT INTO sqlite_stat1
VALUES('data','data_mimetype_data1_index','9819 2455 3');
INSERT INTO sqlite_stat1 VALUES('data','data_raw_contact_id','9819 7');
INSERT INTO sqlite_stat1 VALUES('accounts',NULL,'1');
DROP TABLE IF EXISTS sqlite_stat3;
ANALYZE sqlite_master;
EXPLAIN QUERY PLAN
SELECT * FROM
data JOIN mimetypes ON (data.mimetype_id=mimetypes._id)
JOIN raw_contacts ON (data.raw_contact_id=raw_contacts._id)
JOIN accounts ON (raw_contacts.account_id=accounts._id)
WHERE mimetype_id=10 AND data14 IS NOT NULL;
} {/SEARCH TABLE data .*SEARCH TABLE raw_contacts/}
do_execsql_test autoindex1-801 {
EXPLAIN QUERY PLAN
SELECT * FROM
data JOIN mimetypes ON (data.mimetype_id=mimetypes._id)
JOIN raw_contacts ON (data.raw_contact_id=raw_contacts._id)
JOIN accounts ON (raw_contacts.account_id=accounts._id)
WHERE mimetypes._id=10 AND data14 IS NOT NULL;
} {/SEARCH TABLE data .*SEARCH TABLE raw_contacts/}
finish_test

50
test/transitive1.test Normal file
View File

@ -0,0 +1,50 @@
# 2013 April 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. The
# focus of this script is testing of transitive WHERE clause constraints
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
do_execsql_test transitive1-100 {
CREATE TABLE t1(a TEXT, b TEXT, c TEXT COLLATE NOCASE);
INSERT INTO t1 VALUES('abc','abc','Abc');
INSERT INTO t1 VALUES('def','def','def');
INSERT INTO t1 VALUES('ghi','ghi','GHI');
CREATE INDEX t1a1 ON t1(a);
CREATE INDEX t1a2 ON t1(a COLLATE nocase);
SELECT * FROM t1 WHERE a=b AND c=b AND c='DEF';
} {def def def}
do_execsql_test transitive1-110 {
SELECT * FROM t1 WHERE a=b AND c=b AND c>='DEF' ORDER BY +a;
} {def def def ghi ghi GHI}
do_execsql_test transitive1-120 {
SELECT * FROM t1 WHERE a=b AND c=b AND c<='DEF' ORDER BY +a;
} {abc abc Abc def def def}
do_execsql_test transitive1-200 {
CREATE TABLE t2(a INTEGER, b INTEGER, c TEXT);
INSERT INTO t2 VALUES(100,100,100);
INSERT INTO t2 VALUES(20,20,20);
INSERT INTO t2 VALUES(3,3,3);
SELECT * FROM t2 WHERE a=b AND c=b AND c=20;
} {20 20 20}
do_execsql_test transitive1-210 {
SELECT * FROM t2 WHERE a=b AND c=b AND c>=20 ORDER BY +a;
} {3 3 3 20 20 20}
do_execsql_test transitive1-220 {
SELECT * FROM t2 WHERE a=b AND c=b AND c<=20 ORDER BY +a;
} {20 20 20 100 100 100}
finish_test