Enhance the query planner so that it is able to code EXISTS operators in

the WHERE clause as if they were IN operators, when appropriate.

FossilOrigin-Name: c1862abb44873f06ec0d772469d8a2d128ae4670b1e98c2d97b0e2da18df9a04
This commit is contained in:
drh 2021-01-18 12:35:16 +00:00
commit abc6b67aff
7 changed files with 540 additions and 10 deletions

View File

@ -1,5 +1,5 @@
C Fix\sa\shyperlink\sin\sthe\sLemon\sdocumentation.
D 2021-01-16T12:15:41.192
C Enhance\sthe\squery\splanner\sso\sthat\sit\sis\sable\sto\scode\sEXISTS\soperators\sin\nthe\sWHERE\sclause\sas\sif\sthey\swere\sIN\soperators,\swhen\sappropriate.
D 2021-01-18T12:35:16.581
F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1
F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea
F LICENSE.md df5091916dbb40e6e9686186587125e1b2ff51f022cc334e886c19a0e9982724
@ -492,7 +492,7 @@ F src/date.c dace306a10d9b02ee553d454c8e1cf8d3c9b932e137738a6b15b90253a9bfc10
F src/dbpage.c 8a01e865bf8bc6d7b1844b4314443a6436c07c3efe1d488ed89e81719047833a
F src/dbstat.c 3aa79fc3aed7ce906e4ea6c10e85d657299e304f6049861fe300053ac57de36c
F src/delete.c 927cf8f900583e79aca8f1a321979e0a8f053babd9a690b44b38f79de2cc09fe
F src/expr.c 0d196ed5a2ebf96be7e8df88add4fabfad0dce16c0fed81a4b8f6a26e259797f
F src/expr.c 47c85263e6d179424e6b09e2c79db5704ab5b8cbc2fae2ee3285faa2566f2e74
F src/fault.c 460f3e55994363812d9d60844b2a6de88826e007
F src/fkey.c 83372403298e6a7dd989a47aaacdbaa5b4307b5199dbd56e07d4896066b3de72
F src/func.c 251b5953cecd0ce3e282213c5e623134415793d3569d7804d13460559d7e45ff
@ -545,7 +545,7 @@ F src/shell.c.in 9ebc74e4f05cfbd0f4a36060fdaeff1da4e9af4458358722bc08c5a1ab9a087
F src/sqlite.h.in 0af968a1fa3c717261e1df0ed105fa7bddb4d82de7e0adb3eab49e6aa81b4de7
F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8
F src/sqlite3ext.h 61b38c073d5e1e96a3d45271b257aef27d0d13da2bea5347692ae579475cd95e
F src/sqliteInt.h 6aad58a5ae1374e18ea53d0c3ea71f047b67313426767783bd7fa14ee786725a
F src/sqliteInt.h d921214bba203960de10ea7a9183735ec362a5def5910d468282a8f82e8b4c26
F src/sqliteLimit.h d7323ffea5208c6af2734574bae933ca8ed2ab728083caa117c9738581a31657
F src/status.c 4b8bc2a6905163a38b739854a35b826c737333fab5b1f8e03fa7eb9a4799c4c1
F src/table.c 0f141b58a16de7e2fbe81c308379e7279f4c6b50eb08efeec5892794a0ba30d1
@ -630,7 +630,7 @@ F src/walker.c d9c4e454ebb9499e908aa62d55b8994c375cf5355ac78f60d45af17f7890701c
F src/where.c 0e6abb22a2323fec80b450825593c26a2ad8f4815d1ee3af9969d8f6144bf681
F src/whereInt.h 9a3f577619f07700d16d89eeb2f3d94d6b7ed7f109c2dacf0ce8844921549506
F src/wherecode.c a3a1aff30fe99a818d8e7c607980f033f40c68d890e03ed25838b9dbb7908bee
F src/whereexpr.c 3a463e156ea388083c501502229c2c7f4f5c6b5330ea59bdf40d6eb6e155a25f
F src/whereexpr.c a022b4f447c0fb0674e172a9a303537ea5055df60d579f99cec7ead18e8c453f
F src/window.c edd6f5e25a1e8f2b6f5305b7f5f7da7bb35f07f0d432b255b1d4c2fcab4205aa
F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2
F test/affinity2.test ce1aafc86e110685b324e9a763eab4f2a73f737842ec3b687bd965867de90627
@ -874,6 +874,8 @@ F test/exclusive.test 7ff63be7503990921838d5c9f77f6e33e68e48ed1a9d48cd28745bf650
F test/exclusive2.test 984090e8e9d1b331d2e8111daf6e5d61dda0bef7
F test/exec.test e949714dc127eaa5ecc7d723efec1ec27118fdd7
F test/exists.test 79a75323c78f02bbe9c251ea502a092f9ef63dac
F test/exists2.test 3e5726d6a67ebd4bd3466db58be424c09156c1f276c7594abb260cbf6ad494d3
F test/existsfault.test 74f7edc713f5a335e7ff47adf503067bf05c6f8630f88b2a19c24f0fa5486ab8
F test/expr.test 26cd01e8485bc48c8aa6a1add598e9ce1e706b4eb4f3f554e0b0223022e8c2cf
F test/expr2.test c27327ae9c017a7ff6280123f67aff496f912da74d78c888926d68b46ec75fd8
F test/extension01.test 00d13cec817f331a687a243e0e5a2d87b0e358c9
@ -1895,7 +1897,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 249a71cc6822d6bdd5bb9e727aac81c6549693b418e9c0987b96850ee332c940
R 0d3b2c6d616a91b857e305e5fa92f92c
P 2ffb2ffa0ea147edd88632d2bbe29cc1d66d0911ce8e1068c406c81dd5a20242 92cc29099f796f5f244dd80ee431c48d36d01eaece6f150119ead5ecd14eaae1
R e9622ae2cc2f8f16e772e641d8b24f1c
T +closed 92cc29099f796f5f244dd80ee431c48d36d01eaece6f150119ead5ecd14eaae1
U drh
Z 3e8f8636c650d40fd45e0f7dddeb2d81
Z f5a7eb36d087a773f1b509e693ef42b1

View File

@ -1 +1 @@
2ffb2ffa0ea147edd88632d2bbe29cc1d66d0911ce8e1068c406c81dd5a20242
c1862abb44873f06ec0d772469d8a2d128ae4670b1e98c2d97b0e2da18df9a04

View File

@ -95,7 +95,18 @@ Expr *sqlite3ExprAddCollateToken(
const Token *pCollName, /* Name of collating sequence */
int dequote /* True to dequote pCollName */
){
if( pCollName->n>0 ){
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; i<pList->nExpr; i++){
pList->a[i].pExpr = sqlite3ExprAddCollateToken(pParse,pList->a[i].pExpr,
pCollName, dequote);
}
}
}else if( pCollName->n>0 ){
Expr *pNew = sqlite3ExprAlloc(pParse->db, TK_COLLATE, pCollName, dequote);
if( pNew ){
pNew->pLeft = pExpr;

View File

@ -1721,6 +1721,7 @@ 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 */
/*

View File

@ -1007,6 +1007,271 @@ 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; ii<pSrc->nSrc; 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 *p, Select *pSelect){
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 <here> ...) */
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 <srclist> WHERE <e1> = <e2> AND <e3>)
**
** The virtual IN() term added is:
**
** <e1> IN (SELECT <e2> FROM <srclist> WHERE <e3>)
**
** 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 <e1> 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 <srclist>).
**
** 4. <e2> and <e3> must not refer to any values from the outer query.
** In other words, once <e1> 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) || pSel->pWin ) return;
if( pSel->pPrior ) return;
if( pSel->pWhere==0 ) 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
** "pExpr" field filled in. The job of this routine is to analyze the
@ -1192,6 +1457,16 @@ static void exprAnalyze(
}
#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);
}
}
#ifndef SQLITE_OMIT_LIKE_OPTIMIZATION
/* Add constraints to reduce the search space on a LIKE or GLOB
** operator.

188
test/exists2.test Normal file
View File

@ -0,0 +1,188 @@
# 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 TABLE 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 TABLE 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 TABLE 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 TABLE 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 TABLE 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 TABLE 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 TABLE 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 TABLE 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 TABLE 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 TABLE 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
}
# 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

52
test/existsfault.test Normal file
View File

@ -0,0 +1,52 @@
# 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