For queries with both ORDER BY and LIMIT, if the rows of the inner loop are

emitted in ORDER BY order and the LIMIT has been reached, then optimize by
exiting the inner loop and continuing with the next cycle of the first outer
loop.

FossilOrigin-Name: 559733b09e9630fac9d9318a7ecbaba9134e9160
This commit is contained in:
drh 2016-05-20 14:11:37 +00:00
commit 1524c672e9
7 changed files with 160 additions and 18 deletions

View File

@ -1,5 +1,5 @@
C Autoconf\sconfigure.ac\sadjustment\sto\stry\sto\sget\sit\sto\slook\sfor\sboth\seditline\nand\sreadline\sautomatically.
D 2016-05-20T12:22:16.170
C For\squeries\swith\sboth\sORDER\sBY\sand\sLIMIT,\sif\sthe\srows\sof\sthe\sinner\sloop\sare\nemitted\sin\sORDER\sBY\sorder\sand\sthe\sLIMIT\shas\sbeen\sreached,\sthen\soptimize\sby\nexiting\sthe\sinner\sloop\sand\scontinuing\swith\sthe\snext\scycle\sof\sthe\sfirst\souter\nloop.
D 2016-05-20T14:11:37.786
F Makefile.in f59e0763ff448719fc1bd25513882b0567286317
F Makefile.linux-gcc 7bc79876b875010e8c8f9502eb935ca92aa3c434
F Makefile.msc 306d73e854b1a92ea06e5d1e637faa5c44de53c7
@ -378,12 +378,12 @@ F src/printf.c a5f0ca08ddede803c241266abb46356ec748ded1
F src/random.c ba2679f80ec82c4190062d756f22d0c358180696
F src/resolve.c cca3aa77b95706df5d635a2141a4d1de60ae6598
F src/rowset.c 49eb91c588a2bab36647368e031dc5b66928149d
F src/select.c fd4a7ce2937497181063cfedb92058ac89491a5d
F src/select.c a0c4abf54bc6bd3a9c77a36ef3d1676045706cb2
F src/shell.c 14ff7f660530a52b117d110ba3390b7b2eb719b6
F src/sqlite.h.in 9984129d86243424b765fcb3f147c697bd20bb54
F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8
F src/sqlite3ext.h 98f72cbfe00169c39089115427d06ea05fe4b4a2
F src/sqliteInt.h 19de316bfce65ff074b379a67b493a446f3cf8ee
F src/sqliteInt.h 09621b4b7dba808b24262c2480ea75b045001853
F src/sqliteLimit.h c0373387c287c8d0932510b5547ecde31b5da247
F src/status.c 70912d7be68e9e2dbc4010c93d344af61d4c59ba
F src/table.c 5226df15ab9179b9ed558d89575ea0ce37b03fc9
@ -458,8 +458,8 @@ F src/vxworks.h d2988f4e5a61a4dfe82c6524dd3d6e4f2ce3cdb9
F src/wal.c 4db22ed7e77bcf672b1a685d6ddeffba8d5be302
F src/wal.h 2f7c831cf3b071fa548bf2d5cac640846a7ff19c
F src/walker.c 0f142b5bd3ed2041fc52d773880748b212e63354
F src/where.c 72fd2e1258625c1aee8e33a529914aea2d487422
F src/whereInt.h 3b1fc240e322613ba4e9dc857ca9c7c3390acc74
F src/where.c 0e54a03d11d4e99ad25528f42ff4c9a6fa7a23da
F src/whereInt.h 6e18240be400bef8e4dbafea605251707c5dbf49
F src/wherecode.c e3f18fcda2d7f8218a09dc33cf495dca0efa6e3e
F src/whereexpr.c eacc0e60d029a082b4fc0cc42ea98544add1319e
F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2
@ -878,6 +878,7 @@ F test/like.test 81632c437a947bf1f7130b19537da6a1a844806a
F test/like2.test 3b2ee13149ba4a8a60b59756f4e5d345573852da
F test/like3.test 3608a2042b6f922f900fbfd5d3ce4e7eca57f7c4
F test/limit.test 0c99a27a87b14c646a9d583c7c89fd06c352663e
F test/limit2.test 55c9f4d08c89311e00afd75045ee1a2aca205cb4
F test/loadext.test 42a3b8166dfcadcb0e0c8710dc520d97c31a8b98
F test/loadext2.test 0408380b57adca04004247179837a18e866a74f7
F test/lock.test be4fe08118fb988fed741f429b7dd5d65e1c90db
@ -1489,7 +1490,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 58b516e8c0b00a41bc0364eab267bc2ecb9efeff
R 1ccdb41fa76e9f52d7032b7d9c7cb950
P 645bd696dfd86d8c93080f6ebfddbc9639ec088b ed1b30dc932a7c03e173b130c5f55f9989c7e0b4
R b166646a4114a46c17faadb7ecf63948
T +closed ed1b30dc932a7c03e173b130c5f55f9989c7e0b4
U drh
Z 54717b5e62279adb2d1cf6e8a28ff9fe
Z aa696592564772ea00c367935ddfa343

View File

@ -1 +1 @@
645bd696dfd86d8c93080f6ebfddbc9639ec088b
559733b09e9630fac9d9318a7ecbaba9134e9160

View File

@ -56,6 +56,7 @@ struct SortCtx {
int addrSortIndex; /* Address of the OP_SorterOpen or OP_OpenEphemeral */
int labelDone; /* Jump here when done, ex: LIMIT reached */
u8 sortFlags; /* Zero or more SORTFLAG_* bits */
u8 bOrderedInnerLoop; /* ORDER BY correctly sorts the inner loop */
};
#define SORTFLAG_UseSorter 0x01 /* Use SorterOpen instead of OpenEphemeral */
@ -589,9 +590,30 @@ static void pushOntoSorter(
sqlite3VdbeAddOp2(v, op, pSort->iECursor, regRecord);
if( iLimit ){
int addr;
int r1 = 0;
/* Fill the sorter until it contains LIMIT+OFFSET entries. (The iLimit
** register is initialized with value of LIMIT+OFFSET.) After the sorter
** fills up, delete the least entry in the sorter after each insert.
** Thus we never hold more than the LIMIT+OFFSET rows in memory at once */
addr = sqlite3VdbeAddOp3(v, OP_IfNotZero, iLimit, 0, 1); VdbeCoverage(v);
sqlite3VdbeAddOp1(v, OP_Last, pSort->iECursor);
if( pSort->bOrderedInnerLoop ){
r1 = ++pParse->nMem;
sqlite3VdbeAddOp3(v, OP_Column, pSort->iECursor, nExpr, r1);
VdbeComment((v, "seq"));
}
sqlite3VdbeAddOp1(v, OP_Delete, pSort->iECursor);
if( pSort->bOrderedInnerLoop ){
/* If the inner loop is driven by an index such that values from
** the same iteration of the inner loop are in sorted order, then
** immediately jump to the next iteration of an inner loop if the
** entry from the current iteration does not fit into the top
** LIMIT+OFFSET entries of the sorter. */
int iBrk = sqlite3VdbeCurrentAddr(v) + 2;
sqlite3VdbeAddOp3(v, OP_Eq, regBase+nExpr, iBrk, r1);
sqlite3VdbeChangeP5(v, SQLITE_NULLEQ);
VdbeCoverage(v);
}
sqlite3VdbeJumpHere(v, addr);
}
}
@ -5176,6 +5198,7 @@ int sqlite3Select(
}
if( sSort.pOrderBy ){
sSort.nOBSat = sqlite3WhereIsOrdered(pWInfo);
sSort.bOrderedInnerLoop = sqlite3WhereOrderedInnerLoop(pWInfo);
if( sSort.nOBSat==sSort.pOrderBy->nExpr ){
sSort.pOrderBy = 0;
}

View File

@ -2540,7 +2540,7 @@ struct SrcList {
#define WHERE_WANT_DISTINCT 0x0100 /* All output needs to be distinct */
#define WHERE_SORTBYGROUP 0x0200 /* Support sqlite3WhereIsSorted() */
#define WHERE_SEEK_TABLE 0x0400 /* Do not defer seeks on main table */
/* 0x0800 not currently used */
#define WHERE_ORDERBY_LIMIT 0x0800 /* ORDERBY+LIMIT on the inner loop */
/* 0x1000 not currently used */
/* 0x2000 not currently used */
#define WHERE_USE_LIMIT 0x4000 /* Use the LIMIT in cost estimates */
@ -3637,6 +3637,7 @@ void sqlite3WhereEnd(WhereInfo*);
LogEst sqlite3WhereOutputRowCount(WhereInfo*);
int sqlite3WhereIsDistinct(WhereInfo*);
int sqlite3WhereIsOrdered(WhereInfo*);
int sqlite3WhereOrderedInnerLoop(WhereInfo*);
int sqlite3WhereIsSorted(WhereInfo*);
int sqlite3WhereContinueLabel(WhereInfo*);
int sqlite3WhereBreakLabel(WhereInfo*);

View File

@ -51,6 +51,18 @@ int sqlite3WhereIsOrdered(WhereInfo *pWInfo){
return pWInfo->nOBSat;
}
/*
** Return TRUE if the innermost loop of the WHERE clause implementation
** returns rows in ORDER BY order for complete run of the inner loop.
**
** Across multiple iterations of outer loops, the output rows need not be
** sorted. As long as rows are sorted for just the innermost loop, this
** routine can return TRUE.
*/
int sqlite3WhereOrderedInnerLoop(WhereInfo *pWInfo){
return pWInfo->bOrderedInnerLoop;
}
/*
** Return the VDBE address or label to jump to in order to continue
** immediately with the next row of a WHERE clause.
@ -3250,7 +3262,7 @@ static i8 wherePathSatisfiesOrderBy(
WhereInfo *pWInfo, /* The WHERE clause */
ExprList *pOrderBy, /* ORDER BY or GROUP BY or DISTINCT clause to check */
WherePath *pPath, /* The WherePath to check */
u16 wctrlFlags, /* Might contain WHERE_GROUPBY or WHERE_DISTINCTBY */
u16 wctrlFlags, /* WHERE_GROUPBY or _DISTINCTBY or _ORDERBY_LIMIT */
u16 nLoop, /* Number of entries in pPath->aLoop[] */
WhereLoop *pLast, /* Add this WhereLoop to the end of pPath->aLoop[] */
Bitmask *pRevMask /* OUT: Mask of WhereLoops to run in reverse order */
@ -3261,6 +3273,7 @@ static i8 wherePathSatisfiesOrderBy(
u8 isOrderDistinct; /* All prior WhereLoops are order-distinct */
u8 distinctColumns; /* True if the loop has UNIQUE NOT NULL columns */
u8 isMatch; /* iColumn matches a term of the ORDER BY clause */
u16 eqOpMask; /* Allowed equality operators */
u16 nKeyCol; /* Number of key columns in pIndex */
u16 nColumn; /* Total number of ordered columns in the index */
u16 nOrderBy; /* Number terms in the ORDER BY clause */
@ -3311,9 +3324,16 @@ static i8 wherePathSatisfiesOrderBy(
obDone = MASKBIT(nOrderBy)-1;
orderDistinctMask = 0;
ready = 0;
eqOpMask = WO_EQ | WO_IS | WO_ISNULL;
if( wctrlFlags & WHERE_ORDERBY_LIMIT ) eqOpMask |= WO_IN;
for(iLoop=0; isOrderDistinct && obSat<obDone && iLoop<=nLoop; iLoop++){
if( iLoop>0 ) ready |= pLoop->maskSelf;
pLoop = iLoop<nLoop ? pPath->aLoop[iLoop] : pLast;
if( iLoop<nLoop ){
pLoop = pPath->aLoop[iLoop];
if( wctrlFlags & WHERE_ORDERBY_LIMIT ) continue;
}else{
pLoop = pLast;
}
if( pLoop->wsFlags & WHERE_VIRTUALTABLE ){
if( pLoop->u.vtab.isOrdered ) obSat = obDone;
break;
@ -3331,7 +3351,7 @@ static i8 wherePathSatisfiesOrderBy(
if( pOBExpr->op!=TK_COLUMN ) continue;
if( pOBExpr->iTable!=iCur ) continue;
pTerm = sqlite3WhereFindTerm(&pWInfo->sWC, iCur, pOBExpr->iColumn,
~ready, WO_EQ|WO_ISNULL|WO_IS, 0);
~ready, eqOpMask, 0);
if( pTerm==0 ) continue;
if( (pTerm->eOperator&(WO_EQ|WO_IS))!=0 && pOBExpr->iColumn>=0 ){
const char *z1, *z2;
@ -3371,10 +3391,12 @@ static i8 wherePathSatisfiesOrderBy(
for(j=0; j<nColumn; j++){
u8 bOnce; /* True to run the ORDER BY search loop */
/* Skip over == and IS NULL terms */
/* Skip over == and IS and ISNULL terms.
** (Also skip IN terms when doing WHERE_ORDERBY_LIMIT processing)
*/
if( j<pLoop->u.btree.nEq
&& pLoop->nSkip==0
&& ((i = pLoop->aLTerm[j]->eOperator) & (WO_EQ|WO_ISNULL|WO_IS))!=0
&& ((i = pLoop->aLTerm[j]->eOperator) & eqOpMask)!=0
){
if( i & WO_ISNULL ){
testcase( isOrderDistinct );
@ -3898,8 +3920,19 @@ static int wherePathSolver(WhereInfo *pWInfo, LogEst nRowEst){
}
}else{
pWInfo->nOBSat = pFrom->isOrdered;
if( pWInfo->nOBSat<0 ) pWInfo->nOBSat = 0;
pWInfo->revMask = pFrom->revLoop;
if( pWInfo->nOBSat<=0 ){
pWInfo->nOBSat = 0;
if( nLoop>0 ){
Bitmask m;
int rc = wherePathSatisfiesOrderBy(pWInfo, pWInfo->pOrderBy, pFrom,
WHERE_ORDERBY_LIMIT, nLoop-1, pFrom->aLoop[nLoop-1], &m);
if( rc==pWInfo->pOrderBy->nExpr ){
pWInfo->bOrderedInnerLoop = 1;
pWInfo->revMask = m;
}
}
}
}
if( (pWInfo->wctrlFlags & WHERE_SORTBYGROUP)
&& pWInfo->nOBSat==pWInfo->pOrderBy->nExpr && nLoop>0

View File

@ -418,8 +418,9 @@ struct WhereInfo {
u8 sorted; /* True if really sorted (not just grouped) */
u8 eOnePass; /* ONEPASS_OFF, or _SINGLE, or _MULTI */
u8 untestedTerms; /* Not all WHERE terms resolved by outer loop */
u8 eDistinct; /* One of the WHERE_DISTINCT_* values below */
u8 eDistinct; /* One of the WHERE_DISTINCT_* values */
u8 nLevel; /* Number of nested loop */
u8 bOrderedInnerLoop; /* True if only the inner-most loop is ordered */
int iTop; /* The very beginning of the WHERE loop */
int iContinue; /* Jump here to continue with next record */
int iBreak; /* Jump here to break out of the loop */

82
test/limit2.test Normal file
View File

@ -0,0 +1,82 @@
# 2016-05-20
#
# 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 the LIMIT in combination with ORDER BY
# and in particular, the optimizations in the inner loop that cause an
# early exit of the inner loop when the LIMIT is reached and the inner
# loop is emitting rows in ORDER BY order.
set testdir [file dirname $argv0]
source $testdir/tester.tcl
do_execsql_test limit2-100 {
CREATE TABLE t1(a,b);
WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<1000)
INSERT INTO t1(a,b) SELECT 1, (x*17)%1000 + 1000 FROM c;
INSERT INTO t1(a,b) VALUES(2,2),(3,1006),(4,4),(5,9999);
CREATE INDEX t1ab ON t1(a,b);
}
set sqlite_search_count 0
do_execsql_test limit2-100.1 {
SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY b LIMIT 5;
} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |}
set fast_count $sqlite_search_count
set sqlite_search_count 0
do_execsql_test limit2-100.2 {
SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY +b LIMIT 5;
} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |}
do_test limit2-100.3 {
set slow_count $sqlite_search_count
expr {$fast_count < 0.02*$slow_count}
} {1}
do_execsql_test limit2-110 {
CREATE TABLE t2(x,y);
INSERT INTO t2(x,y) VALUES('a',1),('a',2),('a',3),('a',4);
INSERT INTO t2(x,y) VALUES('b',1),('c',2),('d',3),('e',4);
CREATE INDEX t2xy ON t2(x,y);
}
set sqlite_search_count 0
do_execsql_test limit2-110.1 {
SELECT a, b, '|' FROM t2, t1 WHERE t2.x='a' AND t1.a=t2.y ORDER BY t1.b LIMIT 5;
} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |}
set fast_count $sqlite_search_count
set sqlite_search_count 0
do_execsql_test limit2-110.2 {
SELECT a, b, '|' FROM t2, t1 WHERE t2.x='a' AND t1.a=t2.y ORDER BY +t1.b LIMIT 5;
} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |}
set slow_count $sqlite_search_count
do_test limit2-110.3 {
expr {$fast_count < 0.02*$slow_count}
} {1}
do_execsql_test limit2-120 {
DROP INDEX t1ab;
CREATE INDEX t1ab ON t1(a,b DESC);
}
set sqlite_search_count 0
do_execsql_test limit2-120.1 {
SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY b DESC LIMIT 5;
} {5 9999 | 1 1999 | 1 1998 | 1 1997 | 1 1996 |}
set fast_count $sqlite_search_count
set sqlite_search_count 0
do_execsql_test limit2-120.2 {
SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY +b DESC LIMIT 5;
} {5 9999 | 1 1999 | 1 1998 | 1 1997 | 1 1996 |}
do_test limit2-120.3 {
set slow_count $sqlite_search_count
expr {$fast_count < 0.02*$slow_count}
} {1}
finish_test