From: drh <> Date: Tue, 4 May 2021 12:07:16 +0000 (+0000) Subject: Back out the EXISTS-to-IN optimization. It slows things down rather than X-Git-Tag: version-3.36.0~122 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=433a3e935de3d4dbfe81e7626e7d511ae3700e1b;p=thirdparty%2Fsqlite.git Back out the EXISTS-to-IN optimization. It slows things down rather than speeds them up depending on the query. And (see [forum:/forumpost/8692d94725|forum post 8692d94725]) it sometimes results in an incorrect answer. We may come back and revisit this optimization later, but for now it seems best just to disable it. FossilOrigin-Name: 16252d73fa73569fd7506676f6ffbbcd43addfb105384fb74449d30ca720904a --- diff --git a/manifest b/manifest index 0c22447bdc..ec778d924b 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Fix\sminor\scoverity\swarnings\sin\sthe\sCLI. -D 2021-05-03T13:35:00.853 +C Back\sout\sthe\sEXISTS-to-IN\soptimization.\s\sIt\sslows\sthings\sdown\srather\sthan\nspeeds\sthem\sup\sdepending\son\sthe\squery.\s\sAnd\s(see\n[forum:/forumpost/8692d94725|forum\spost\s8692d94725])\sit\ssometimes\sresults\sin\nan\sincorrect\sanswer.\s\sWe\smay\scome\sback\sand\srevisit\sthis\soptimization\slater,\nbut\sfor\snow\sit\sseems\sbest\sjust\sto\sdisable\sit. +D 2021-05-04T12:07:16.531 F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1 F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea F LICENSE.md df5091916dbb40e6e9686186587125e1b2ff51f022cc334e886c19a0e9982724 @@ -495,7 +495,7 @@ F src/date.c e0632f335952b32401482d099321bbf12716b29d6e72836b53ae49683ebae4bf F src/dbpage.c 8a01e865bf8bc6d7b1844b4314443a6436c07c3efe1d488ed89e81719047833a F src/dbstat.c 3aa79fc3aed7ce906e4ea6c10e85d657299e304f6049861fe300053ac57de36c F src/delete.c 73f57a9a183532c344a3135cf8f2a5589376e39183e0b5f562d6b61b2af0f4d8 -F src/expr.c 70e2cf6e270bb97ab6602336c82060bee0720cd887483f85c645ac1df97d4a34 +F src/expr.c 1d5171fe602cd56ab8b9c9ecbd48d9917e6020cafd6bd87ceac5949e8a1ed2d8 F src/fault.c 460f3e55994363812d9d60844b2a6de88826e007 F src/fkey.c e9063648396c58778f77583a678342fe4a9bc82436bf23c5f9f444f2df0fdaa4 F src/func.c 88fd711754a7241cb9f8eb1391370fd0c0cea756b3358efa274c5d1efd59af93 @@ -548,7 +548,7 @@ F src/shell.c.in 7725921bdd612c7a5cadc30db81ce17a5d522ccb61b6771359429ec20f20c85 F src/sqlite.h.in 325474dd22536800a5ffe9da4c12f753086a5b75aa8ecb22b3eb89b96003c3f6 F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8 F src/sqlite3ext.h 61b38c073d5e1e96a3d45271b257aef27d0d13da2bea5347692ae579475cd95e -F src/sqliteInt.h a00cc0642e2a4e26367313dc553781253e278a0e571e7211cc56245a8db3e0e7 +F src/sqliteInt.h fa1af0cba6b07c7423da78572c8182ccba4eaf897407af43a78b301345ede8d0 F src/sqliteLimit.h d7323ffea5208c6af2734574bae933ca8ed2ab728083caa117c9738581a31657 F src/status.c 4b8bc2a6905163a38b739854a35b826c737333fab5b1f8e03fa7eb9a4799c4c1 F src/table.c 0f141b58a16de7e2fbe81c308379e7279f4c6b50eb08efeec5892794a0ba30d1 @@ -633,7 +633,7 @@ F src/walker.c 6e540867a30d81e00205995fa2dc0e3d25365a7402251c9fd5d19aa4ff5e60b6 F src/where.c 33bae7248e206b874456982a07b859acd880fb7b137678b2dc1e277c234b8b6f F src/whereInt.h 446e5e8018f83358ef917cf32d8e6a86dc8430113d0b17e720f1839d3faa44c4 F src/wherecode.c 992bf0d7520bffd345472fb9bc83a1ca0134e46d9e904879bb21e1e77957fcc3 -F src/whereexpr.c d8cafcf6781cf871082f04d7540862cf0fe30cb381dd1b2145a380376364fe8e +F src/whereexpr.c 811f339ca85540157f3a400333ba90237ffbe7a2ba82dac63ce0677f4c4109d0 F src/window.c 2e092a03ee2e7e6541dd44fa6cb4cd0abdd142fc9c9ed6bac2788daa53316e33 F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2 F test/affinity2.test ce1aafc86e110685b324e9a763eab4f2a73f737842ec3b687bd965867de90627 @@ -884,8 +884,6 @@ F test/exclusive.test 7ff63be7503990921838d5c9f77f6e33e68e48ed1a9d48cd28745bf650 F test/exclusive2.test 984090e8e9d1b331d2e8111daf6e5d61dda0bef7 F test/exec.test e949714dc127eaa5ecc7d723efec1ec27118fdd7 F test/exists.test 79a75323c78f02bbe9c251ea502a092f9ef63dac -F test/exists2.test 92d563a97019a70f7adcbe3cbaab16f9fc696affbf0f9ede1796ea5f7cc5a3ac -F test/existsfault.test 72a0036c1424d9204d49f4d976c3277a1b8bb2eed3c67aa124ba2df2f1331c7c F test/expr.test 26cd01e8485bc48c8aa6a1add598e9ce1e706b4eb4f3f554e0b0223022e8c2cf F test/expr2.test c27327ae9c017a7ff6280123f67aff496f912da74d78c888926d68b46ec75fd8 F test/exprfault.test 497cc0b8fe6a677f49b55cb485e040f709ec2834b84f25912fe9c2dfeeda33db @@ -1914,7 +1912,8 @@ F vsixtest/vsixtest.tcl 6a9a6ab600c25a91a7acc6293828957a386a8a93 F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0 -P 5127f7376776e6220eb8f83a30aa6b823c23ae0ac76e7ae41b33ca4e03ce236a -R f037b4ec26eae2b6b1667d1bcd74e769 +P 204086a94202fc631371b75c7a8286df2f66116399628ac27ef54533641b8f20 +Q -c1862abb44873f06ec0d772469d8a2d128ae4670b1e98c2d97b0e2da18df9a04 +R f628cb24055240816ba06b9a4320261c U drh -Z db8934e8c24fc9eaaad92bc8aa68e8cf +Z 02e047978739c3f696576a32fee6343b diff --git a/manifest.uuid b/manifest.uuid index 7897a801c3..2df7af8290 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -204086a94202fc631371b75c7a8286df2f66116399628ac27ef54533641b8f20 \ No newline at end of file +16252d73fa73569fd7506676f6ffbbcd43addfb105384fb74449d30ca720904a \ No newline at end of file diff --git a/src/expr.c b/src/expr.c index 1402609311..7a2df30fd0 100644 --- a/src/expr.c +++ b/src/expr.c @@ -95,18 +95,7 @@ Expr *sqlite3ExprAddCollateToken( const Token *pCollName, /* Name of collating sequence */ int dequote /* True to dequote pCollName */ ){ - assert( pExpr!=0 || pParse->db->mallocFailed ); - if( pExpr==0 ) return 0; - if( pExpr->op==TK_VECTOR ){ - ExprList *pList = pExpr->x.pList; - if( ALWAYS(pList!=0) ){ - int i; - for(i=0; inExpr; i++){ - pList->a[i].pExpr = sqlite3ExprAddCollateToken(pParse,pList->a[i].pExpr, - pCollName, dequote); - } - } - }else if( pCollName->n>0 ){ + if( pCollName->n>0 ){ Expr *pNew = sqlite3ExprAlloc(pParse->db, TK_COLLATE, pCollName, dequote); if( pNew ){ pNew->pLeft = pExpr; diff --git a/src/sqliteInt.h b/src/sqliteInt.h index b8b6b340dc..54880ab029 100644 --- a/src/sqliteInt.h +++ b/src/sqliteInt.h @@ -1731,7 +1731,6 @@ struct sqlite3 { #define SQLITE_SkipScan 0x00004000 /* Skip-scans */ #define SQLITE_PropagateConst 0x00008000 /* The constant propagation opt */ #define SQLITE_MinMaxOpt 0x00010000 /* The min/max optimization */ -#define SQLITE_ExistsToIN 0x00020000 /* The EXISTS-to-IN optimization */ #define SQLITE_AllOpts 0xffffffff /* All optimizations */ /* diff --git a/src/whereexpr.c b/src/whereexpr.c index 1807fbb000..9d8a25f8c2 100644 --- a/src/whereexpr.c +++ b/src/whereexpr.c @@ -1008,276 +1008,6 @@ static int exprMightBeIndexed( return exprMightBeIndexed2(pFrom,mPrereq,aiCurCol,pExpr); } -/* -** Expression callback for exprUsesSrclist(). -*/ -static int exprUsesSrclistCb(Walker *p, Expr *pExpr){ - if( pExpr->op==TK_COLUMN ){ - SrcList *pSrc = p->u.pSrcList; - int iCsr = pExpr->iTable; - int ii; - for(ii=0; iinSrc; ii++){ - if( pSrc->a[ii].iCursor==iCsr ){ - return p->eCode ? WRC_Abort : WRC_Continue; - } - } - return p->eCode ? WRC_Continue : WRC_Abort; - } - return WRC_Continue; -} - -/* -** Select callback for exprUsesSrclist(). -*/ -static int exprUsesSrclistSelectCb(Walker *NotUsed1, Select *NotUsed2){ - UNUSED_PARAMETER(NotUsed1); - UNUSED_PARAMETER(NotUsed2); - return WRC_Abort; -} - -/* -** This function always returns true if expression pExpr contains -** a sub-select. -** -** If there is no sub-select in pExpr, then return true if pExpr -** contains a TK_COLUMN node for a table that is (bUses==1) -** or is not (bUses==0) in pSrc. -** -** Said another way: -** -** bUses Return Meaning -** -------- ------ ------------------------------------------------ -** -** bUses==1 true pExpr contains either a sub-select or a -** TK_COLUMN referencing pSrc. -** -** bUses==1 false pExpr contains no sub-selects and all TK_COLUMN -** nodes reference tables not found in pSrc -** -** bUses==0 true pExpr contains either a sub-select or a TK_COLUMN -** that references a table not in pSrc. -** -** bUses==0 false pExpr contains no sub-selects and all TK_COLUMN -** nodes reference pSrc -*/ -static int exprUsesSrclist(SrcList *pSrc, Expr *pExpr, int bUses){ - Walker sWalker; - memset(&sWalker, 0, sizeof(Walker)); - sWalker.eCode = bUses; - sWalker.u.pSrcList = pSrc; - sWalker.xExprCallback = exprUsesSrclistCb; - sWalker.xSelectCallback = exprUsesSrclistSelectCb; - return (sqlite3WalkExpr(&sWalker, pExpr)==WRC_Abort); -} - -/* -** Context object used by exprExistsToInIter() as it iterates through an -** expression tree. -*/ -struct ExistsToInCtx { - SrcList *pSrc; /* The tables in an EXISTS(SELECT ... FROM ...) */ - Expr *pInLhs; /* OUT: Use this as the LHS of the IN operator */ - Expr *pEq; /* OUT: The == term that include pInLhs */ - Expr **ppAnd; /* OUT: The AND operator that includes pEq as a child */ - Expr **ppParent; /* The AND operator currently being examined */ -}; - -/* -** Iterate through all AND connected nodes in the expression tree -** headed by (*ppExpr), populating the structure passed as the first -** argument with the values required by exprAnalyzeExistsFindEq(). -** -** This function returns non-zero if the expression tree does not meet -** the two conditions described by the header comment for -** exprAnalyzeExistsFindEq(), or zero if it does. -*/ -static int exprExistsToInIter(struct ExistsToInCtx *p, Expr **ppExpr){ - Expr *pExpr = *ppExpr; - switch( pExpr->op ){ - case TK_AND: - p->ppParent = ppExpr; - if( exprExistsToInIter(p, &pExpr->pLeft) ) return 1; - p->ppParent = ppExpr; - if( exprExistsToInIter(p, &pExpr->pRight) ) return 1; - break; - case TK_EQ: { - int bLeft = exprUsesSrclist(p->pSrc, pExpr->pLeft, 0); - int bRight = exprUsesSrclist(p->pSrc, pExpr->pRight, 0); - if( bLeft || bRight ){ - if( (bLeft && bRight) || p->pInLhs ) return 1; - p->pInLhs = bLeft ? pExpr->pLeft : pExpr->pRight; - if( exprUsesSrclist(p->pSrc, p->pInLhs, 1) ) return 1; - p->pEq = pExpr; - p->ppAnd = p->ppParent; - } - break; - } - default: - if( exprUsesSrclist(p->pSrc, pExpr, 0) ){ - return 1; - } - break; - } - - return 0; -} - -/* -** This function is used by exprAnalyzeExists() when creating virtual IN(...) -** terms equivalent to user-supplied EXIST(...) clauses. It splits the WHERE -** clause of the Select object passed as the first argument into one or more -** expressions joined by AND operators, and then tests if the following are -** true: -** -** 1. Exactly one of the AND separated terms refers to the outer -** query, and it is an == (TK_EQ) expression. -** -** 2. Only one side of the == expression refers to the outer query, and -** it does not refer to any columns from the inner query. -** -** If both these conditions are true, then a pointer to the side of the == -** expression that refers to the outer query is returned. The caller will -** use this expression as the LHS of the IN(...) virtual term. Or, if one -** or both of the above conditions are not true, NULL is returned. -** -** If non-NULL is returned and ppEq is non-NULL, *ppEq is set to point -** to the == expression node before returning. If pppAnd is non-NULL and -** the == node is not the root of the WHERE clause, then *pppAnd is set -** to point to the pointer to the AND node that is the parent of the == -** node within the WHERE expression tree. -*/ -static Expr *exprAnalyzeExistsFindEq( - Select *pSel, /* The SELECT of the EXISTS */ - Expr **ppEq, /* OUT: == node from WHERE clause */ - Expr ***pppAnd /* OUT: Pointer to parent of ==, if any */ -){ - struct ExistsToInCtx ctx; - memset(&ctx, 0, sizeof(ctx)); - ctx.pSrc = pSel->pSrc; - if( exprExistsToInIter(&ctx, &pSel->pWhere) ){ - return 0; - } - if( ppEq ) *ppEq = ctx.pEq; - if( pppAnd ) *pppAnd = ctx.ppAnd; - return ctx.pInLhs; -} - -/* -** Term idxTerm of the WHERE clause passed as the second argument is an -** EXISTS expression with a correlated SELECT statement on the RHS. -** This function analyzes the SELECT statement, and if possible adds an -** equivalent "? IN(SELECT...)" virtual term to the WHERE clause. -** -** For an EXISTS term such as the following: -** -** EXISTS (SELECT ... FROM WHERE = AND ) -** -** The virtual IN() term added is: -** -** IN (SELECT FROM WHERE ) -** -** The virtual term is only added if the following conditions are met: -** -** 1. The sub-select must not be an aggregate or use window functions, -** -** 2. The sub-select must not be a compound SELECT, -** -** 3. Expression must refer to at least one column from the outer -** query, and must not refer to any column from the inner query -** (i.e. from ). -** -** 4. and must not refer to any values from the outer query. -** In other words, once has been removed, the inner query -** must not be correlated. -** -*/ -static void exprAnalyzeExists( - SrcList *pSrc, /* the FROM clause */ - WhereClause *pWC, /* the WHERE clause */ - int idxTerm /* Index of the term to be analyzed */ -){ - Parse *pParse = pWC->pWInfo->pParse; - WhereTerm *pTerm = &pWC->a[idxTerm]; - Expr *pExpr = pTerm->pExpr; - Select *pSel = pExpr->x.pSelect; - Expr *pDup = 0; - Expr *pEq = 0; - Expr *pRet = 0; - Expr *pInLhs = 0; - Expr **ppAnd = 0; - int idxNew; - sqlite3 *db = pParse->db; - - assert( pExpr->op==TK_EXISTS ); - assert( (pExpr->flags & EP_VarSelect) && (pExpr->flags & EP_xIsSelect) ); - - if( pSel->selFlags & SF_Aggregate ) return; -#ifndef SQLITE_OMIT_WINDOWFUNC - if( pSel->pWin ) return; -#endif - if( pSel->pPrior ) return; - if( pSel->pWhere==0 ) return; - if( pSel->pLimit ) return; - if( 0==exprAnalyzeExistsFindEq(pSel, 0, 0) ) return; - - pDup = sqlite3ExprDup(db, pExpr, 0); - if( db->mallocFailed ){ - sqlite3ExprDelete(db, pDup); - return; - } - pSel = pDup->x.pSelect; - sqlite3ExprListDelete(db, pSel->pEList); - pSel->pEList = 0; - - pInLhs = exprAnalyzeExistsFindEq(pSel, &pEq, &ppAnd); - assert( pInLhs && pEq ); - assert( pEq==pSel->pWhere || ppAnd ); - if( pInLhs==pEq->pLeft ){ - pRet = pEq->pRight; - }else{ - CollSeq *p = sqlite3ExprCompareCollSeq(pParse, pEq); - pInLhs = sqlite3ExprAddCollateString(pParse, pInLhs, p?p->zName:"BINARY"); - pRet = pEq->pLeft; - } - - assert( pDup->pLeft==0 ); - pDup->op = TK_IN; - pDup->pLeft = pInLhs; - pDup->flags &= ~EP_VarSelect; - if( pRet->op==TK_VECTOR ){ - pSel->pEList = pRet->x.pList; - pRet->x.pList = 0; - sqlite3ExprDelete(db, pRet); - }else{ - pSel->pEList = sqlite3ExprListAppend(pParse, 0, pRet); - } - pEq->pLeft = 0; - pEq->pRight = 0; - if( ppAnd ){ - Expr *pAnd = *ppAnd; - Expr *pOther = (pAnd->pLeft==pEq) ? pAnd->pRight : pAnd->pLeft; - pAnd->pLeft = pAnd->pRight = 0; - sqlite3ExprDelete(db, pAnd); - *ppAnd = pOther; - }else{ - assert( pSel->pWhere==pEq ); - pSel->pWhere = 0; - } - sqlite3ExprDelete(db, pEq); - -#ifdef WHERETRACE_ENABLED /* 0x20 */ - if( sqlite3WhereTrace & 0x20 ){ - sqlite3DebugPrintf("Convert EXISTS:\n"); - sqlite3TreeViewExpr(0, pExpr, 0); - sqlite3DebugPrintf("into IN:\n"); - sqlite3TreeViewExpr(0, pDup, 0); - } -#endif - idxNew = whereClauseInsert(pWC, pDup, TERM_VIRTUAL|TERM_DYNAMIC); - exprAnalyze(pSrc, pWC, idxNew); - markTermAsChild(pWC, idxNew, idxTerm); - pWC->a[idxTerm].wtFlags |= TERM_COPIED; -} /* ** The input to this routine is an WhereTerm structure with only the @@ -1469,16 +1199,6 @@ static void exprAnalyze( pTerm = &pWC->a[idxTerm]; } #endif /* SQLITE_OMIT_OR_OPTIMIZATION */ - - else if( pExpr->op==TK_EXISTS ){ - /* Perhaps treat an EXISTS operator as an IN operator */ - if( (pExpr->flags & EP_VarSelect)!=0 - && OptimizationEnabled(db, SQLITE_ExistsToIN) - ){ - exprAnalyzeExists(pSrc, pWC, idxTerm); - } - } - /* The form "x IS NOT NULL" can sometimes be evaluated more efficiently ** as "x>NULL" if x is not an INTEGER PRIMARY KEY. So construct a ** virtual term of that form. diff --git a/test/exists2.test b/test/exists2.test deleted file mode 100644 index 498b90dd28..0000000000 --- a/test/exists2.test +++ /dev/null @@ -1,194 +0,0 @@ -# 2021 January 15 -# -# 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 file is testing cases where EXISTS expressions are -# transformed to IN() expressions by where.c -# - -set testdir [file dirname $argv0] -source $testdir/tester.tcl -set testprefix exists2 - -do_execsql_test 1.0 { - CREATE TABLE t1(a INTEGER PRIMARY KEY, b); - INSERT INTO t1 VALUES(1, 'one'); - INSERT INTO t1 VALUES(2, 'two'); - INSERT INTO t1 VALUES(3, 'three'); - INSERT INTO t1 VALUES(4, 'four'); - INSERT INTO t1 VALUES(5, 'five'); - INSERT INTO t1 VALUES(6, 'six'); - INSERT INTO t1 VALUES(7, 'seven'); - - CREATE TABLE t2(c INTEGER, d INTEGER); - INSERT INTO t2 VALUES(1, 1); - INSERT INTO t2 VALUES(3, 2); - INSERT INTO t2 VALUES(5, 3); - INSERT INTO t2 VALUES(7, 4); -} - -proc do_execsql_eqp_test {tn sql eqp res} { - uplevel [list do_eqp_test $tn.1 $sql [string trim $eqp]] - uplevel [list do_execsql_test $tn.2 $sql $res] -} - -do_execsql_eqp_test 1.1 { - SELECT t1.* FROM t1 WHERE EXISTS(SELECT * FROM t2 WHERE t1.a=t2.c); -} { - USING INTEGER PRIMARY KEY -} { - 1 one 3 three 5 five 7 seven -} - -do_execsql_eqp_test 1.2 { - SELECT t1.* FROM t1 WHERE EXISTS(SELECT * FROM t2 WHERE t2.c=t1.a); -} { - SEARCH t1 USING INTEGER PRIMARY KEY -} { - 1 one 3 three 5 five 7 seven -} - -do_execsql_eqp_test 1.3 { - SELECT t1.* FROM t1 WHERE EXISTS(SELECT * FROM t2 WHERE t2.c+1=t1.a); -} { - SEARCH t1 USING INTEGER PRIMARY KEY -} { - 2 two 4 four 6 six -} - -do_execsql_eqp_test 1.4 { - SELECT t1.* FROM t1 WHERE EXISTS(SELECT * FROM t2 WHERE t2.c+1=t1.a+1); -} { - SCAN t1 -} { - 1 one 3 three 5 five 7 seven -} - -do_execsql_eqp_test 1.5 { - SELECT t1.* FROM t1 WHERE EXISTS( - SELECT * FROM t2 WHERE t1.a=t2.c AND d IN (1, 2, 3) - ); -} { - SEARCH t1 USING INTEGER PRIMARY KEY -} { - 1 one 3 three 5 five -} - -do_execsql_eqp_test 1.6 { - SELECT t1.* FROM t1 WHERE EXISTS( - SELECT * FROM t2 WHERE d IN (1, 2, 3)AND t1.a=t2.c - ); -} { - SEARCH t1 USING INTEGER PRIMARY KEY -} { - 1 one 3 three 5 five -} - -do_execsql_eqp_test 1.7 { - SELECT t1.* FROM t1 WHERE EXISTS( - SELECT * FROM t2 WHERE d IN (1, 2, 3)AND t1.a=t2.c - ); -} { - SEARCH t1 USING INTEGER PRIMARY KEY -} { - 1 one 3 three 5 five -} - -#------------------------------------------------------------------------- -# -reset_db -do_execsql_test 2.0 { - CREATE TABLE t3(a TEXT PRIMARY KEY, b TEXT, x INT) WITHOUT ROWID; - CREATE TABLE t4(c TEXT COLLATE nocase, y INT); - - INSERT INTO t3 VALUES('one', 'i', 1); - INSERT INTO t3 VALUES('two', 'ii', 2); - INSERT INTO t3 VALUES('three', 'iii', 3); - INSERT INTO t3 VALUES('four', 'iv', 4); - INSERT INTO t3 VALUES('five', 'v', 5); - - INSERT INTO t4 VALUES('FIVE',5), ('four',4), ('TWO',2), ('one',1); -} - -do_execsql_test 2.1 { SELECT a FROM t3, t4 WHERE a=c } {four one} -do_execsql_test 2.2 { SELECT a FROM t3, t4 WHERE c=a } {five four one two} - -do_execsql_eqp_test 2.3 { - SELECT a FROM t3 WHERE EXISTS (SELECT 1 FROM t4 WHERE a=c) -} { - SEARCH t3 USING PRIMARY KEY -} { - four one -} - -do_execsql_eqp_test 2.4 { - SELECT a FROM t3 WHERE EXISTS (SELECT 1 FROM t4 WHERE c=a) -} { - SCAN t3 -} { - five four one two -} - -do_execsql_test 2.5 { - CREATE INDEX t3anc ON t3(a COLLATE nocase, x); -} - -do_execsql_eqp_test 2.6 { - SELECT a FROM t3 WHERE EXISTS (SELECT 1 FROM t4 WHERE c=a) -} { - SEARCH t3 USING COVERING INDEX t3anc -} { - five four one two -} -do_execsql_test 2.6a { - SELECT a FROM t3 WHERE EXISTS (SELECT 1 FROM t4 WHERE (c,y)=(a,x)) -} {five four one two} - -do_execsql_eqp_test 2.7 { - SELECT a FROM t3 WHERE EXISTS (SELECT 1 FROM t4 WHERE a=c) -} { - SEARCH t3 USING PRIMARY KEY -} { - four one -} -do_execsql_test 2.7a { - SELECT a FROM t3 WHERE EXISTS (SELECT 1 FROM t4 WHERE (a,x)=(c,y)) -} { - four one -} - -do_execsql_test 2.7b { - SELECT a FROM t3 WHERE EXISTS (SELECT 1 FROM t4 WHERE (a,x)=(c,y) LIMIT 1) -} { - four one -} - -# EXISTS clauses using vector expressions in the WHERE clause. -# -reset_db -do_execsql_test 3.0 { - CREATE TABLE t1(a,b); - INSERT INTO t1(a,b) VALUES(1,111),(2,222),(8,888); - CREATE TABLE t2(x INTEGER PRIMARY KEY, y); - INSERT INTO t2(x,y) VALUES(2,222),(3,333),(7,333); - SELECT y FROM t2 WHERE EXISTS(SELECT 1 FROM t1 WHERE (x,y)=(a,b)); -} {222} -do_execsql_test 3.1 { - SELECT y FROM t2 WHERE EXISTS(SELECT 1 FROM t1 WHERE (a,b)=(x,y)); -} {222} -do_execsql_test 3.2 { - SELECT y FROM t2 WHERE EXISTS(SELECT 1 FROM t1 WHERE (x,b)=(a,y)); -} {222} - - - - - -finish_test diff --git a/test/existsfault.test b/test/existsfault.test deleted file mode 100644 index 4a33eeb357..0000000000 --- a/test/existsfault.test +++ /dev/null @@ -1,51 +0,0 @@ -# 2021 January 15 -# -# 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 file is testing cases where EXISTS expressions are -# transformed to IN() expressions by where.c -# - -set testdir [file dirname $argv0] -source $testdir/tester.tcl -set testprefix existsfault - -do_execsql_test 1 { - CREATE TABLE t1(a PRIMARY KEY, b); - INSERT INTO t1 VALUES(1, 'one'); - INSERT INTO t1 VALUES(2, 'two'); - INSERT INTO t1 VALUES(3, 'three'); - INSERT INTO t1 VALUES(4, 'four'); - INSERT INTO t1 VALUES(5, 'five'); - INSERT INTO t1 VALUES(6, 'six'); - INSERT INTO t1 VALUES(7, 'seven'); - - CREATE TABLE t2(c INTEGER, d INTEGER); - INSERT INTO t2 VALUES(1, 1); - INSERT INTO t2 VALUES(3, 2); - INSERT INTO t2 VALUES(5, 3); - INSERT INTO t2 VALUES(7, 4); -} -faultsim_save_and_close - -do_faultsim_test 1 -prep { - faultsim_restore_and_reopen -} -body { - execsql { - SELECT t1.* FROM t1 WHERE EXISTS( - SELECT * FROM t2 WHERE t2.c=t1.a AND d IN (1, 2, 3) - ) - } -} -test { - faultsim_test_result {0 {1 one 3 three 5 five}} -} - - -finish_test