Optimizer now converts OR-connected WHERE-clause terms into an IN operator so
that they can be used with indices. There are known problems with the ORDER BY optimization in this and in several prior check-ins. This check-in is not recommended for production use. (CVS 2569) FossilOrigin-Name: d23c8bf81e508722e92ff1b9c8bc98dc026a31f2
This commit is contained in:
parent
ed37800693
commit
6c30be8e51
16
manifest
16
manifest
@ -1,5 +1,5 @@
|
||||
C The\sBETWEEN\soperator\sin\sa\sWHERE\sclause\sis\snow\sable\sto\suse\sindices.\s(CVS\s2568)
|
||||
D 2005-07-28T23:12:08
|
||||
C Optimizer\snow\sconverts\sOR-connected\sWHERE-clause\sterms\sinto\san\sIN\soperator\sso\nthat\sthey\scan\sbe\sused\swith\sindices.\s\sThere\sare\sknown\sproblems\swith\sthe\nORDER\sBY\soptimization\sin\sthis\sand\sin\sseveral\sprior\scheck-ins.\s\sThis\ncheck-in\sis\snot\srecommended\sfor\sproduction\suse.\s(CVS\s2569)
|
||||
D 2005-07-29T15:10:18
|
||||
F Makefile.in 22ea9c0fe748f591712d8fe3c6d972c6c173a165
|
||||
F Makefile.linux-gcc 06be33b2a9ad4f005a5f42b22c4a19dab3cbb5c7
|
||||
F README 9c4e2d6706bdcc3efdd773ce752a8cdab4f90028
|
||||
@ -38,7 +38,7 @@ F src/callback.c 0910b611e0c158f107ee3ff86f8a371654971e2b
|
||||
F src/date.c 7444b0900a28da77e57e3337a636873cff0ae940
|
||||
F src/delete.c be1fc25c9e109cd8cbab42a43ee696263da7c04b
|
||||
F src/experimental.c 50c1e3b34f752f4ac10c36f287db095c2b61766d
|
||||
F src/expr.c 0e158f7cc8df562320faa9f2de48cfd856458a52
|
||||
F src/expr.c c71265b78d383382fa8798ac9436246e3eb6d16c
|
||||
F src/func.c 2be0799df0c05066a29e589485ebee0b3f756a15
|
||||
F src/hash.c 2b1b13f7400e179631c83a1be0c664608c8f021f
|
||||
F src/hash.h 1b0c445e1c89ff2aaad9b4605ba61375af001e84
|
||||
@ -85,7 +85,7 @@ F src/vdbeapi.c 7f392f0792d1258c958083d7de9eae7c3530c9a6
|
||||
F src/vdbeaux.c 3732a86566a6be4da4c606e9334baf3fd98667af
|
||||
F src/vdbefifo.c b8805850afe13b43f1de78d58088cb5d66f88e1e
|
||||
F src/vdbemem.c da8e8d6f29dd1323f782f000d7cd120027c9ff03
|
||||
F src/where.c c37799a796f490695211189608e1d5abeb01eea8
|
||||
F src/where.c c65782be9fff4fd95e4e652f815bbcfd36d5656f
|
||||
F tclinstaller.tcl 046e3624671962dc50f0481d7c25b38ef803eb42
|
||||
F test/all.test 7f0988442ab811dfa41793b5b550f5828ce316f3
|
||||
F test/alter.test 9d6837a3d946b73df692b7cef2a7644d2e2f6bc6
|
||||
@ -226,7 +226,7 @@ F test/vacuum2.test 5d77e98c458bcdbeecc6327de5107179ba1aa095
|
||||
F test/varint.test ab7b110089a08b9926ed7390e7e97bdefeb74102
|
||||
F test/view.test 3c79232a2ee45918c62a0cf90411525899404a76
|
||||
F test/where.test b6ab0f64adc5fbb4259f284b19da6cd9aeadc711
|
||||
F test/where2.test 8696c35cd31b0a298de046f3fb6b684486a8b472
|
||||
F test/where2.test 6e8c3369e315a609b207734f57a49e21ed838c04
|
||||
F tool/diffdb.c 7524b1b5df217c20cd0431f6789851a4e0cb191b
|
||||
F tool/lemon.c c88936c67f6411608db8fa4254d254f509fa40f6
|
||||
F tool/lempar.c f0c30abcae762a7d1eb37cd88b2232ab8dd625fb
|
||||
@ -289,7 +289,7 @@ F www/tclsqlite.tcl 425be741b8ae664f55cb1ef2371aab0a75109cf9
|
||||
F www/vdbe.tcl 87a31ace769f20d3627a64fa1fade7fed47b90d0
|
||||
F www/version3.tcl a99cf5f6d8bd4d5537584a2b342f0fb9fa601d8b
|
||||
F www/whentouse.tcl 528299b8316726dbcc5548e9aa0648c8b1bd055b
|
||||
P 4b02703dec71aa78e5f8d8cab5b950966a4c6abc
|
||||
R 5cec6ff48a1212708f6b9493ee851780
|
||||
P cdf8c9584b945212e065e044df801c207aedb675
|
||||
R 5611aa11dab02620cd1e954cb8436ec6
|
||||
U drh
|
||||
Z 6e3389c38b1260ced7a3d44c47196b06
|
||||
Z 0d093f02ef16efa0e6b90a80fd1aefbf
|
||||
|
@ -1 +1 @@
|
||||
cdf8c9584b945212e065e044df801c207aedb675
|
||||
d23c8bf81e508722e92ff1b9c8bc98dc026a31f2
|
@ -12,7 +12,7 @@
|
||||
** This file contains routines used for analyzing expressions and
|
||||
** for generating VDBE code that evaluates expressions in SQLite.
|
||||
**
|
||||
** $Id: expr.c,v 1.213 2005/07/21 18:23:20 drh Exp $
|
||||
** $Id: expr.c,v 1.214 2005/07/29 15:10:18 drh Exp $
|
||||
*/
|
||||
#include "sqliteInt.h"
|
||||
#include <ctype.h>
|
||||
@ -1334,7 +1334,7 @@ void sqlite3CodeSubselect(Parse *pParse, Expr *pExpr){
|
||||
** this code only executes once. Because for a non-constant
|
||||
** expression we need to rerun this code each time.
|
||||
*/
|
||||
if( testAddr>=0 && !sqlite3ExprIsConstant(pE2) ){
|
||||
if( testAddr>0 && !sqlite3ExprIsConstant(pE2) ){
|
||||
VdbeOp *aOp = sqlite3VdbeGetOp(v, testAddr-1);
|
||||
int i;
|
||||
for(i=0; i<4; i++){
|
||||
|
110
src/where.c
110
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.156 2005/07/28 23:12:08 drh Exp $
|
||||
** $Id: where.c,v 1.157 2005/07/29 15:10:18 drh Exp $
|
||||
*/
|
||||
#include "sqliteInt.h"
|
||||
|
||||
@ -82,10 +82,10 @@ struct WhereTerm {
|
||||
Expr *pExpr; /* Pointer to the subexpression */
|
||||
u16 idx; /* Index of this term in pWC->a[] */
|
||||
i16 iPartner; /* Disable pWC->a[iPartner] when this term disabled */
|
||||
u16 flags; /* Bit flags. See below */
|
||||
i16 leftCursor; /* Cursor number of X in "X <op> <expr>" */
|
||||
i16 leftColumn; /* Column number of X in "X <op> <expr>" */
|
||||
u16 operator; /* A WO_xx value describing <op> */
|
||||
u8 flags; /* Bit flags. See below */
|
||||
u8 nPartner; /* Number of partners that must disable us */
|
||||
WhereClause *pWC; /* The clause this term is part of */
|
||||
Bitmask prereqRight; /* Bitmask of tables used by pRight */
|
||||
@ -95,9 +95,11 @@ struct WhereTerm {
|
||||
/*
|
||||
** Allowed values of WhereTerm.flags
|
||||
*/
|
||||
#define TERM_DYNAMIC 0x0001 /* Need to call sqlite3ExprDelete(pExpr) */
|
||||
#define TERM_VIRTUAL 0x0002 /* Added by the optimizer. Do not code */
|
||||
#define TERM_CODED 0x0004 /* This term is already coded */
|
||||
#define TERM_DYNAMIC 0x01 /* Need to call sqlite3ExprDelete(pExpr) */
|
||||
#define TERM_VIRTUAL 0x02 /* Added by the optimizer. Do not code */
|
||||
#define TERM_CODED 0x04 /* This term is already coded */
|
||||
#define TERM_PARTNERED 0x08 /* Has a virtual partner */
|
||||
#define TERM_OR_OK 0x10 /* Used during OR-clause processing */
|
||||
|
||||
/*
|
||||
** An instance of the following structure holds all information about a
|
||||
@ -225,8 +227,9 @@ static WhereTerm *whereClauseInsert(WhereClause *pWC, Expr *p, int flags){
|
||||
|
||||
/*
|
||||
** This routine identifies subexpressions in the WHERE clause where
|
||||
** each subexpression is separate by the AND operator. aSlot is
|
||||
** filled with pointers to the subexpressions. For example:
|
||||
** each subexpression is separate by the AND operator or some other
|
||||
** operator specified in the op parameter. The WhereClause structure
|
||||
** is filled with pointers to subexpressions. For example:
|
||||
**
|
||||
** WHERE a=='hello' AND coalesce(b,11)<10 AND (c+12!=d OR c==22)
|
||||
** \________/ \_______________/ \________________/
|
||||
@ -239,13 +242,13 @@ static WhereTerm *whereClauseInsert(WhereClause *pWC, Expr *p, int flags){
|
||||
** the WhereClause.a[] array. This array grows as needed to contain
|
||||
** all terms of the WHERE clause.
|
||||
*/
|
||||
static void whereSplit(WhereClause *pWC, Expr *pExpr){
|
||||
static void whereSplit(WhereClause *pWC, Expr *pExpr, int op){
|
||||
if( pExpr==0 ) return;
|
||||
if( pExpr->op!=TK_AND ){
|
||||
if( pExpr->op!=op ){
|
||||
whereClauseInsert(pWC, pExpr, 0);
|
||||
}else{
|
||||
whereSplit(pWC, pExpr->pLeft);
|
||||
whereSplit(pWC, pExpr->pRight);
|
||||
whereSplit(pWC, pExpr->pLeft, op);
|
||||
whereSplit(pWC, pExpr->pRight, op);
|
||||
}
|
||||
}
|
||||
|
||||
@ -433,6 +436,26 @@ static WhereTerm *findTerm(
|
||||
return 0;
|
||||
}
|
||||
|
||||
/* Forward reference */
|
||||
static void exprAnalyze(SrcList*, ExprMaskSet*, WhereTerm*);
|
||||
|
||||
/*
|
||||
** Call exprAnalyze on all terms in a WHERE clause.
|
||||
**
|
||||
**
|
||||
*/
|
||||
static void exprAnalyzeAll(
|
||||
SrcList *pTabList, /* the FROM clause */
|
||||
ExprMaskSet *pMaskSet, /* table masks */
|
||||
WhereClause *pWC /* the WHERE clause to be analyzed */
|
||||
){
|
||||
WhereTerm *pTerm;
|
||||
int i;
|
||||
for(i=pWC->nTerm-1, pTerm=pWC->a; i>=0; i--, pTerm++){
|
||||
exprAnalyze(pTabList, pMaskSet, pTerm);
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
** 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
|
||||
@ -479,6 +502,7 @@ static void exprAnalyze(
|
||||
if( pNew==0 ) return;
|
||||
pNew->iPartner = pTerm->idx;
|
||||
pTerm->nPartner = 1;
|
||||
pTerm->flags |= TERM_PARTNERED;
|
||||
}else{
|
||||
pDup = pExpr;
|
||||
pNew = pTerm;
|
||||
@ -515,7 +539,63 @@ static void exprAnalyze(
|
||||
pTerm->nPartner = 2;
|
||||
}
|
||||
|
||||
|
||||
/* Attempt to convert OR-connected terms into an IN operator so that
|
||||
** they can make use of indices.
|
||||
*/
|
||||
else if( pExpr->op==TK_OR ){
|
||||
int ok;
|
||||
int i, j;
|
||||
int iColumn, iCursor;
|
||||
WhereClause sOr;
|
||||
WhereTerm *pOrTerm;
|
||||
|
||||
assert( (pTerm->flags & TERM_DYNAMIC)==0 );
|
||||
whereClauseInit(&sOr, pTerm->pWC->pParse);
|
||||
whereSplit(&sOr, pExpr, TK_OR);
|
||||
exprAnalyzeAll(pSrc, pMaskSet, &sOr);
|
||||
assert( sOr.nTerm>0 );
|
||||
j = 0;
|
||||
do{
|
||||
iColumn = sOr.a[j].leftColumn;
|
||||
iCursor = sOr.a[j].leftCursor;
|
||||
ok = iCursor>=0;
|
||||
for(i=sOr.nTerm-1, pOrTerm=sOr.a; i>=0 && ok; i--, pOrTerm++){
|
||||
if( pOrTerm->operator!=WO_EQ ){
|
||||
goto or_not_possible;
|
||||
}
|
||||
if( pOrTerm->leftCursor==iCursor && pOrTerm->leftColumn==iColumn ){
|
||||
pOrTerm->flags |= TERM_OR_OK;
|
||||
}else if( (pOrTerm->flags & TERM_PARTNERED)!=0 ||
|
||||
((pOrTerm->flags & TERM_VIRTUAL)!=0 &&
|
||||
(sOr.a[pOrTerm->iPartner].flags & TERM_OR_OK)!=0) ){
|
||||
pOrTerm->flags &= ~TERM_OR_OK;
|
||||
}else{
|
||||
ok = 0;
|
||||
}
|
||||
}
|
||||
}while( !ok && (sOr.a[j++].flags & TERM_PARTNERED)!=0 && j<sOr.nTerm );
|
||||
if( ok ){
|
||||
ExprList *pList = 0;
|
||||
Expr *pNew, *pDup;
|
||||
for(i=sOr.nTerm-1, pOrTerm=sOr.a; i>=0 && ok; i--, pOrTerm++){
|
||||
if( (pOrTerm->flags & TERM_OR_OK)==0 ) continue;
|
||||
pDup = sqlite3ExprDup(pOrTerm->pExpr->pRight);
|
||||
pList = sqlite3ExprListAppend(pList, pDup, 0);
|
||||
}
|
||||
pDup = sqlite3Expr(TK_COLUMN, 0, 0, 0);
|
||||
if( pDup ){
|
||||
pDup->iTable = iCursor;
|
||||
pDup->iColumn = iColumn;
|
||||
}
|
||||
pNew = sqlite3Expr(TK_IN, pDup, 0, 0);
|
||||
if( pNew ) pNew->pList = pList;
|
||||
pTerm->pExpr = pNew;
|
||||
pTerm->flags |= TERM_DYNAMIC;
|
||||
exprAnalyze(pSrc, pMaskSet, pTerm);
|
||||
}
|
||||
or_not_possible:
|
||||
whereClauseClear(&sOr);
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
@ -1196,7 +1276,7 @@ WhereInfo *sqlite3WhereBegin(
|
||||
*/
|
||||
initMaskSet(&maskSet);
|
||||
whereClauseInit(&wc, pParse);
|
||||
whereSplit(&wc, pWhere);
|
||||
whereSplit(&wc, pWhere, TK_AND);
|
||||
|
||||
/* Allocate and initialize the WhereInfo structure that will become the
|
||||
** return value.
|
||||
@ -1225,9 +1305,7 @@ WhereInfo *sqlite3WhereBegin(
|
||||
for(i=0; i<pTabList->nSrc; i++){
|
||||
createMask(&maskSet, pTabList->a[i].iCursor);
|
||||
}
|
||||
for(i=wc.nTerm-1; i>=0; i--){
|
||||
exprAnalyze(pTabList, &maskSet, &wc.a[i]);
|
||||
}
|
||||
exprAnalyzeAll(pTabList, &maskSet, &wc);
|
||||
|
||||
/* Chose the best index to use for each table in the FROM clause.
|
||||
**
|
||||
|
@ -12,7 +12,7 @@
|
||||
# focus of this file is testing the use of indices in WHERE clauses
|
||||
# based on recent changes to the optimizer.
|
||||
#
|
||||
# $Id: where2.test,v 1.2 2005/07/28 23:12:08 drh Exp $
|
||||
# $Id: where2.test,v 1.3 2005/07/29 15:10:19 drh Exp $
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
@ -201,6 +201,45 @@ do_test where2-5.2 {
|
||||
}
|
||||
} {99 6 10000 10006 sort t1 i1w}
|
||||
|
||||
integrity_check {where2-99.0}
|
||||
# Verify that OR clauses get translated into IN operators.
|
||||
#
|
||||
do_test where2-6.1 {
|
||||
queryplan {
|
||||
SELECT * FROM t1 WHERE w=99 OR w=100 ORDER BY +w
|
||||
}
|
||||
} {99 6 10000 10006 100 6 10201 10207 sort t1 i1w}
|
||||
do_test where2-6.2 {
|
||||
queryplan {
|
||||
SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=w ORDER BY +w
|
||||
}
|
||||
} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 i1w}
|
||||
do_test where2-6.3 {
|
||||
queryplan {
|
||||
SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=+w ORDER BY +w
|
||||
}
|
||||
} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 {}}
|
||||
do_test where2-6.4 {
|
||||
queryplan {
|
||||
SELECT * FROM t1 WHERE w=99 OR +w=100 OR 6=w ORDER BY +w
|
||||
}
|
||||
} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 {}}
|
||||
if 0 { ##### FIX ME #####
|
||||
do_test where2-6.5 {
|
||||
queryplan {
|
||||
SELECT b.* FROM t1 a, t1 b
|
||||
WHERE a.w=1 AND (a.y=b.z OR b.z=10)
|
||||
ORDER BY +b.w
|
||||
}
|
||||
} {1 0 4 4 2 1 9 10 sort a i1w b i1zyx}
|
||||
do_test where2-6.6 {
|
||||
queryplan {
|
||||
SELECT b.* FROM t1 a, t1 b
|
||||
WHERE a.w=1 AND (b.z=10 OR a.y=b.z OR b.z=10)
|
||||
ORDER BY +b.w
|
||||
}
|
||||
} {1 0 4 4 2 1 9 10 sort a i1w b i1zyx}
|
||||
}
|
||||
|
||||
|
||||
|
||||
finish_test
|
||||
|
Loading…
Reference in New Issue
Block a user