The query optimizer now attempts to satisfy an ORDER BY clause using

an index.  Sorting is still used if there are no suitable indices. (CVS 628)

FossilOrigin-Name: f09e19b43ef61073713cf32282c90ea666229eba
This commit is contained in:
drh 2002-06-19 14:27:05 +00:00
parent c2bb7c3dd9
commit e31847449e
10 changed files with 270 additions and 48 deletions

View File

@ -1 +1 @@
2.5.0
2.5.1

View File

@ -1,9 +1,9 @@
C Version\s2.5.0\s(CVS\s627)
D 2002-06-17T17:26:39
C The\squery\soptimizer\snow\sattempts\sto\ssatisfy\san\sORDER\sBY\sclause\susing\nan\sindex.\s\sSorting\sis\sstill\sused\sif\sthere\sare\sno\ssuitable\sindices.\s(CVS\s628)
D 2002-06-19T14:27:05
F Makefile.in 6291a33b87d2a395aafd7646ee1ed562c6f2c28c
F Makefile.template 4e11752e0b5c7a043ca50af4296ec562857ba495
F README a4c0ba11354ef6ba0776b400d057c59da47a4cc0
F VERSION 4d924d02a7c61b0eb53a6fc5c6fc9536b9b6f212
F VERSION 9a1a4bc4ca9e44b3ccf4c764cb670aae41b078a0
F aclocal.m4 11faa843caa38fd451bc6aeb43e248d1723a269d
F config.guess f38b1e93d1e0fa6f5a6913e9e7b12774b9232588
F config.sub f14b07d544ca26b5d698259045136b783e18fc7f
@ -21,7 +21,7 @@ F src/TODO af7f3cab0228e34149cf98e073aa83d45878e7e6
F src/btree.c 8b86be8f234c1c5dab3186f69cee2544ec9d7257
F src/btree.h 8abeabfe6e0b1a990b64fa457592a6482f6674f3
F src/build.c f4633493f57660587c35c76dc7948f5da691a718
F src/delete.c 15789fc723a6776309945b13a79f9a0e78275fc0
F src/delete.c 44c45460b1e03033756e35adc6d569ffbf30b725
F src/encode.c 346b12b46148506c32038524b95c4631ab46d760
F src/expr.c ec0689af4e355356df47dc1514ff17523d2f9c71
F src/func.c b8d0fd3011f53ea0e46b6bab857612eb36b5d1ea
@ -37,11 +37,11 @@ F src/pager.h 6fddfddd3b73aa8abc081b973886320e3c614f0e
F src/parse.y 2285d8967d7334d52a2188089e5a881d73ba56f6
F src/printf.c 236ed7a79386feed4456fa728fff8be793f1547c
F src/random.c 19e8e00fe0df32a742f115773f57651be327cabe
F src/select.c 6c3a92d7a0bdf3448265d530cc0e6f6e5a764997
F src/select.c 514b4b12f72df68e0c8b4187af302b7c22b22cf6
F src/shell.c 1d22fe870ee852cfb975fd000dbe3973713d0a15
F src/shell.tcl 27ecbd63dd88396ad16d81ab44f73e6c0ea9d20e
F src/sqlite.h.in 0038faa6d642de06b91143ee65a131bd831d020b
F src/sqliteInt.h ea5c5ce4c321d66934fa1341caf4f32b61e96bec
F src/sqliteInt.h 1e9904f9baa536333d9d1168e075abf96426baad
F src/table.c eed2098c9b577aa17f8abe89313a9c4413f57d63
F src/tclsqlite.c 9300c9606a38bc0c75d6c0bc8a6197ab979353d1
F src/test1.c 5cc4f0bbf38237e04e1b2077e285b41bfb4c4cbf
@ -50,11 +50,11 @@ F src/test3.c 4e52fff8b01f08bd202f7633feda5639b7ba2b5e
F src/threadtest.c 81f0598e0f031c1bd506af337fdc1b7e8dff263f
F src/tokenize.c ac4c46f190346b87da54ec3e2605d160af80c619
F src/trigger.c 21342af6ac031fece39c8fc6eabd1739ca5327c1
F src/update.c 05431e23a9c83502fd7911e771c8366fc2b90b4c
F src/update.c 6f6a4dcd71cd9ff730b7f12c83de5498cde4924f
F src/util.c 876b259f9186e84b944b72e793dd3dad50e63e95
F src/vdbe.c 7d9bb3701ea00576c5d5fb3f3de63af7b7304241
F src/vdbe.h fba15f3280688f6f32f11d1042078e3c557bac43
F src/where.c aa5d9d83abf0f7dda06fdd4235020f2b72d58dec
F src/where.c 1fdb7aca26c1963eb42615a95e0fc2978eec566a
F test/all.test e4d3821eeba751829b419cd47814bd20af4286d1
F test/bigrow.test 8ab252dba108f12ad64e337b0f2ff31a807ac578
F test/btree.test bf326f546a666617367a7033fa2c07451bd4f8e1
@ -108,7 +108,7 @@ F test/unique.test 572aa791327c1e8d797932263e9d67f176cfdb44
F test/update.test a0aa0bf83e6fad8407d0e4ad25ebb09b513f5bf4
F test/vacuum.test 059871b312eb910bbe49dafde1d01490cc2c6bbe
F test/view.test b9851e9142de5e5831fdf18f125cbe1256cb550a
F test/where.test 367d7911ee0522f1bb8a2daf17fb985e06cfe8bb
F test/where.test 1f87bec674bf85d74ac1cc5b2cd3d89be1e87b1d
F tool/lemon.c 459cb2bb3738a1ad5cb0ad8b805587a88a885d95
F tool/lempar.c 73a991cc3017fb34804250fa901488b5147b3717
F tool/memleak.awk 296dfbce7a9ca499b95ce04e30334e64a50052e0
@ -122,7 +122,7 @@ F www/arch.fig d5f9752a4dbf242e9cfffffd3f5762b6c63b3bcf
F www/arch.png 82ef36db1143828a7abc88b1e308a5f55d4336f4
F www/arch.tcl 72a0c80e9054cc7025a50928d28d9c75c02c2b8b
F www/c_interface.tcl 58cf4d128dcae08d91d0011c6d4d11de323f470f
F www/changes.tcl c828c925a15c197f542296d001a07fab705518ab
F www/changes.tcl 31a8fec4f078a60b7de5f19859297f375e9ec8da
F www/conflict.tcl 81dd21f9a679e60aae049e9dd8ab53d59570cda2
F www/crosscompile.tcl 3622ebbe518927a3854a12de51344673eb2dd060
F www/download.tcl 29aa6679ca29621d10613f60ebbbda18f4b91c49
@ -137,7 +137,7 @@ F www/speed.tcl da8afcc1d3ccc5696cfb388a68982bc3d9f7f00f
F www/sqlite.tcl 8b5884354cb615049aed83039f8dfe1552a44279
F www/tclsqlite.tcl 1db15abeb446aad0caf0b95b8b9579720e4ea331
F www/vdbe.tcl 2013852c27a02a091d39a766bc87cff329f21218
P 7a216adea5aa5a82718f8c85f8961ba36ab51bb4
R ec45ebcb2d24be890f6c54c516b827ad
P 9baef3e240c4ffd90881ac4664efd205bd9e65f4
R e3b8c707333c1ebbf7616bf0a643f3ed
U drh
Z 42ee4973064a93c98cc24a8792507f93
Z 9b74fdbff1dc04448a39217a6e95f99b

View File

@ -1 +1 @@
9baef3e240c4ffd90881ac4664efd205bd9e65f4
f09e19b43ef61073713cf32282c90ea666229eba

View File

@ -12,7 +12,7 @@
** This file contains C code routines that are called by the parser
** to handle DELETE FROM statements.
**
** $Id: delete.c,v 1.37 2002/06/11 02:25:41 danielk1977 Exp $
** $Id: delete.c,v 1.38 2002/06/19 14:27:05 drh Exp $
*/
#include "sqliteInt.h"
@ -190,7 +190,7 @@ void sqliteDeleteFrom(
else{
/* Begin the database scan
*/
pWInfo = sqliteWhereBegin(pParse, base, pTabList, pWhere, 1);
pWInfo = sqliteWhereBegin(pParse, base, pTabList, pWhere, 1, 0);
if( pWInfo==0 ) goto delete_from_cleanup;
/* Remember the key of every item to be deleted.

View File

@ -12,7 +12,7 @@
** This file contains C code routines that are called by the parser
** to handle SELECT statements in SQLite.
**
** $Id: select.c,v 1.93 2002/06/14 22:38:42 drh Exp $
** $Id: select.c,v 1.94 2002/06/19 14:27:05 drh Exp $
*/
#include "sqliteInt.h"
@ -1750,7 +1750,7 @@ int sqliteSelect(
/* Begin the database scan
*/
pWInfo = sqliteWhereBegin(pParse, p->base, pTabList, pWhere, 0);
pWInfo = sqliteWhereBegin(pParse, p->base, pTabList, pWhere, 0, &pOrderBy);
if( pWInfo==0 ) goto select_end;
/* Use the standard inner loop if we are not dealing with
@ -1763,7 +1763,7 @@ int sqliteSelect(
}
}
/* If we are dealing with aggregates, then to the special aggregate
/* If we are dealing with aggregates, then do the special aggregate
** processing.
*/
else{

View File

@ -11,7 +11,7 @@
*************************************************************************
** Internal interface definitions for SQLite.
**
** @(#) $Id: sqliteInt.h,v 1.125 2002/06/17 17:07:20 drh Exp $
** @(#) $Id: sqliteInt.h,v 1.126 2002/06/19 14:27:05 drh Exp $
*/
#include "sqlite.h"
#include "hash.h"
@ -862,7 +862,7 @@ Table *sqliteTableNameToTable(Parse*, const char*);
SrcList *sqliteTableTokenToSrcList(Parse*, Token*);
void sqliteDeleteFrom(Parse*, Token*, Expr*);
void sqliteUpdate(Parse*, Token*, ExprList*, Expr*, int);
WhereInfo *sqliteWhereBegin(Parse*, int, SrcList*, Expr*, int);
WhereInfo *sqliteWhereBegin(Parse*, int, SrcList*, Expr*, int, ExprList**);
void sqliteWhereEnd(WhereInfo*);
void sqliteExprCode(Parse*, Expr*);
void sqliteExprIfTrue(Parse*, Expr*, int, int);

View File

@ -12,7 +12,7 @@
** This file contains C code routines that are called by the parser
** to handle UPDATE statements.
**
** $Id: update.c,v 1.44 2002/06/11 02:25:42 danielk1977 Exp $
** $Id: update.c,v 1.45 2002/06/19 14:27:06 drh Exp $
*/
#include "sqliteInt.h"
@ -181,7 +181,7 @@ void sqliteUpdate(
/* Begin the database scan
*/
pWInfo = sqliteWhereBegin(pParse, base, pTabList, pWhere, 1);
pWInfo = sqliteWhereBegin(pParse, base, pTabList, pWhere, 1, 0);
if( pWInfo==0 ) goto update_cleanup;
/* Remember the index of every item to be updated.

View File

@ -13,7 +13,7 @@
** the WHERE clause of SQL statements. Also found here are subroutines
** to generate VDBE code to evaluate expressions.
**
** $Id: where.c,v 1.52 2002/06/14 22:38:43 drh Exp $
** $Id: where.c,v 1.53 2002/06/19 14:27:06 drh Exp $
*/
#include "sqliteInt.h"
@ -25,14 +25,14 @@
typedef struct ExprInfo ExprInfo;
struct ExprInfo {
Expr *p; /* Pointer to the subexpression */
int indexable; /* True if this subexprssion is usable by an index */
int idxLeft; /* p->pLeft is a column in this table number. -1 if
u8 indexable; /* True if this subexprssion is usable by an index */
short int idxLeft; /* p->pLeft is a column in this table number. -1 if
** p->pLeft is not the column of any table */
int idxRight; /* p->pRight is a column in this table number. -1 if
short int idxRight; /* p->pRight is a column in this table number. -1 if
** p->pRight is not the column of any table */
unsigned prereqLeft; /* Tables referenced by p->pLeft */
unsigned prereqRight; /* Tables referenced by p->pRight */
unsigned prereqAll; /* Tables referenced by this expression in any way */
unsigned prereqLeft; /* Bitmask of tables referenced by p->pLeft */
unsigned prereqRight; /* Bitmask of tables referenced by p->pRight */
unsigned prereqAll; /* Bitmask of tables referenced by p */
};
/*
@ -69,15 +69,17 @@ static int exprSplit(int nSlot, ExprInfo *aSlot, Expr *pExpr){
/*
** This routine walks (recursively) an expression tree and generates
** a bitmask indicating which tables are used in that expression
** tree. Bit 0 of the mask is set if table 0 is used. But 1 is set
** if table 1 is used. And so forth.
** tree. Bit 0 of the mask is set if table base+0 is used. Bit 1
** is set if table base+1 is used. And so forth.
**
** In order for this routine to work, the calling function must have
** previously invoked sqliteExprResolveIds() on the expression. See
** the header comment on that routine for additional information.
**
** "base" is the cursor number (the value of the iTable field) that
** corresponds to the first entry in the table list.
** corresponds to the first entry in the list of tables that appear
** in the FROM clause of a SELECT. For UPDATE and DELETE statements
** there is just a single table with "base" as the cursor number.
*/
static int exprTableUsage(int base, Expr *p){
unsigned int mask = 0;
@ -149,7 +151,64 @@ static void exprAnalyze(int base, ExprInfo *pInfo){
}
/*
** Generating the beginning of the loop used for WHERE clause processing.
** pOrderBy is an ORDER BY clause from a SELECT statement. pTab is the
** left-most table in the FROM clause of that same SELECT statement and
** the table has a cursor number of "base".
**
** This routine attempts to find an index for pTab that generates the
** correct record sequence for the given ORDER BY clause. The return value
** is a pointer to an index that does the job. NULL is returned if the
** table has no index that will generate the correct sort order.
**
** If there are two or more indices that generate the correct sort order
** and pPreferredIdx is one of those indices, then return pPreferredIdx.
*/
static Index *findSortingIndex(
Table *pTab, /* The table to be sorted */
int base, /* Cursor number for pTab */
ExprList *pOrderBy, /* The ORDER BY clause */
Index *pPreferredIdx /* Use this index, if possible and not NULL */
){
int i;
Index *pMatch;
Index *pIdx;
assert( pOrderBy!=0 );
assert( pOrderBy->nExpr>0 );
for(i=0; i<pOrderBy->nExpr; i++){
Expr *p;
if( (pOrderBy->a[i].sortOrder & SQLITE_SO_DIRMASK)!=SQLITE_SO_ASC ){
/* Indices can only be used for ascending sort order */
return 0;
}
p = pOrderBy->a[i].pExpr;
if( p->op!=TK_COLUMN || p->iTable!=base ){
/* Can not use an index sort on anything that is not a column in the
** left-most table of the FROM clause */
return 0;
}
}
/* If we get this far, it means the ORDER BY clause consists only of
** ascending columns in the left-most table of the FROM clause. Now
** check for a matching index.
*/
pMatch = 0;
for(pIdx=pTab->pIndex; pIdx; pIdx=pIdx->pNext){
if( pIdx->nColumn<pOrderBy->nExpr ) continue;
for(i=0; i<pOrderBy->nExpr; i++){
if( pOrderBy->a[i].pExpr->iColumn!=pIdx->aiColumn[i] ) break;
}
if( i>=pOrderBy->nExpr ){
pMatch = pIdx;
if( pIdx==pPreferredIdx ) break;
}
}
return pMatch;
}
/*
** Generate the beginning of the loop used for WHERE clause processing.
** The return value is a pointer to an (opaque) structure that contains
** information needed to terminate the loop. Later, the calling routine
** should invoke sqliteWhereEnd() with the return value of this function
@ -204,17 +263,34 @@ static void exprAnalyze(int base, ExprInfo *pInfo){
** ...
** flag = 1
** end
** if flag==0 goto start
** if flag==0 then
** move the row2 cursor to a null row
** goto start
** fi
** end
**
** In words, if the right
** ORDER BY CLAUSE PROCESSING
**
** *ppOrderBy is a pointer to the ORDER BY clause of a SELECT statement,
** if there is one. If there is no ORDER BY clause or if this routine
** is called from an UPDATE or DELETE statement, then ppOrderBy is NULL.
**
** If an index can be used so that the natural output order of the table
** scan is correct for the ORDER BY clause, then that index is used and
** *ppOrderBy is set to NULL. This is an optimization that prevents an
** unnecessary sort of the result set if an index appropriate for the
** ORDER BY clause already exists.
**
** If the where clause loops cannot be arranged to provide the correct
** output order, then the *ppOrderBy is unchanged.
*/
WhereInfo *sqliteWhereBegin(
Parse *pParse, /* The parser context */
int base, /* VDBE cursor index for left-most table in pTabList */
SrcList *pTabList, /* A list of all tables to be scanned */
Expr *pWhere, /* The WHERE clause */
int pushKey /* If TRUE, leave the table key on the stack */
int pushKey, /* If TRUE, leave the table key on the stack */
ExprList **ppOrderBy /* An ORDER BY clause, or NULL */
){
int i; /* Loop counter */
WhereInfo *pWInfo; /* Will become the return value of this function */
@ -235,7 +311,7 @@ WhereInfo *sqliteWhereBegin(
*/
assert( pushKey==0 || pTabList->nSrc==1 );
/* Allocate space for aOrder[] and aiMem[]. */
/* Allocate space for aOrder[] */
aOrder = sqliteMalloc( sizeof(int) * pTabList->nSrc );
/* Allocate and initialize the WhereInfo structure that will become the
@ -496,6 +572,42 @@ WhereInfo *sqliteWhereBegin(
}
}
/* Check to see if the ORDER BY clause is or can be satisfied by the
** use of an index on the first table.
*/
if( ppOrderBy && *ppOrderBy && pTabList->nSrc>0 ){
Index *pSortIdx;
Index *pIdx;
Table *pTab;
pTab = pTabList->a[0].pTab;
pIdx = pWInfo->a[0].pIdx;
if( pIdx && pWInfo->a[0].score==4 ){
/* If there is already an index on the left-most column and it is
** an equality index, then either sorting is not helpful, or the
** index is an IN operator, in which case the index does not give
** the correct sort order. Either way, pretend that no suitable
** index is found.
*/
pSortIdx = 0;
}else if( iDirectEq[0]>=0 || iDirectLt[0]>=0 || iDirectGt[0]>=0 ){
/* If the left-most column is accessed using its ROWID, then do
** not try to sort by index.
*/
pSortIdx = 0;
}else{
pSortIdx = findSortingIndex(pTab, base, *ppOrderBy, pIdx);
}
if( pSortIdx && (pIdx==0 || pIdx==pSortIdx) ){
if( pIdx==0 ){
pWInfo->a[0].pIdx = pSortIdx;
pWInfo->a[0].iCur = pParse->nTab++;
pWInfo->peakNTab = pParse->nTab;
}
*ppOrderBy = 0;
}
}
/* Open all tables in the pTabList and all indices used by those tables.
*/
for(i=0; i<pTabList->nSrc; i++){
@ -577,7 +689,7 @@ WhereInfo *sqliteWhereBegin(
haveKey = 0;
sqliteVdbeAddOp(v, OP_NotExists, base+idx, brk);
pLevel->op = OP_Noop;
}else if( pIdx!=0 && pLevel->score%4==0 ){
}else if( pIdx!=0 && pLevel->score>0 && pLevel->score%4==0 ){
/* Case 2: There is an index and all terms of the WHERE clause that
** refer to the index use the "==" or "IN" operators.
*/
@ -730,6 +842,10 @@ WhereInfo *sqliteWhereBegin(
** form "x=5 AND y<10" then this case is used. Only the
** right-most column can be an inequality - the rest must
** use the "==" operator.
**
** This case is also used when there are no WHERE clause
** constraints but an index is selected anyway, in order
** to force the output order to conform to an ORDER BY.
*/
int score = pLevel->score;
int nEqColumn = score/4;

View File

@ -11,7 +11,7 @@
# This file implements regression tests for SQLite library. The
# focus of this file is testing the use of indices in WHERE clases.
#
# $Id: where.test,v 1.8 2002/06/14 22:38:43 drh Exp $
# $Id: where.test,v 1.9 2002/06/19 14:27:06 drh Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
@ -168,7 +168,7 @@ do_test where-1.36 {
} {1 2 3 6}
do_test where-1.37 {
count {SELECT w FROM t1 WHERE w+1<=4 ORDER BY w}
} {1 2 3 99}
} {1 2 3 199}
# Do the same kind of thing except use a join as the data source.
@ -272,7 +272,7 @@ do_test where-5.2 {
count {
SELECT * FROM t1 WHERE rowid+0 IN (1,2,3,1234) order by 1;
}
} {1 0 4 2 1 9 3 1 16 99}
} {1 0 4 2 1 9 3 1 16 199}
do_test where-5.3 {
count {
SELECT * FROM t1 WHERE w IN (-1,1,2,3) order by 1;
@ -282,7 +282,7 @@ do_test where-5.4 {
count {
SELECT * FROM t1 WHERE w+0 IN (-1,1,2,3) order by 1;
}
} {1 0 4 2 1 9 3 1 16 99}
} {1 0 4 2 1 9 3 1 16 199}
do_test where-5.5 {
count {
SELECT * FROM t1 WHERE rowid IN
@ -296,7 +296,7 @@ do_test where-5.6 {
(select rowid from t1 where rowid IN (-1,2,4))
ORDER BY 1;
}
} {2 1 9 4 2 25 99}
} {2 1 9 4 2 25 199}
do_test where-5.7 {
count {
SELECT * FROM t1 WHERE w IN
@ -310,7 +310,7 @@ do_test where-5.8 {
(select rowid from t1 where rowid IN (-1,2,4))
ORDER BY 1;
}
} {2 1 9 4 2 25 99}
} {2 1 9 4 2 25 199}
do_test where-5.9 {
count {
SELECT * FROM t1 WHERE x IN (1,7) ORDER BY 1;
@ -320,12 +320,12 @@ do_test where-5.10 {
count {
SELECT * FROM t1 WHERE x+0 IN (1,7) ORDER BY 1;
}
} {2 1 9 3 1 16 99}
} {2 1 9 3 1 16 199}
do_test where-5.11 {
count {
SELECT * FROM t1 WHERE y IN (6400,8100) ORDER BY 1;
}
} {79 6 6400 89 6 8100 99}
} {79 6 6400 89 6 8100 199}
do_test where-5.12 {
count {
SELECT * FROM t1 WHERE x=6 AND y IN (6400,8100) ORDER BY 1;
@ -342,6 +342,106 @@ do_test where-5.14 {
}
} {2 1 9 6}
# This procedure executes the SQL. Then it checks the generated program
# for the SQL and appends a "nosort" to the result if the program contains the
# SortCallback opcode. If the program does not contain the SortCallback
# opcode it appends "sort"
#
proc cksort {sql} {
set data [execsql $sql]
set prog [execsql "EXPLAIN $sql"]
if {[regexp SortCallback $prog]} {set x sort} {set x nosort}
lappend data $x
return $data
}
# Check out the logic that attempts to implement the ORDER BY clause
# using an index rather than by sorting.
#
do_test where-6.1 {
execsql {
CREATE TABLE t3(a,b,c);
CREATE INDEX t3a ON t3(a);
CREATE INDEX t3bc ON t3(b,c);
CREATE INDEX t3acb ON t3(a,c,b);
INSERT INTO t3 SELECT w, 101-w, y FROM t1;
SELECT count(*), sum(a), sum(b), sum(c) FROM t3;
}
} {100 5050 5050 348550}
do_test where-6.2 {
cksort {
SELECT * FROM t3 ORDER BY a LIMIT 3
}
} {1 100 4 2 99 9 3 98 16 nosort}
do_test where-6.3 {
cksort {
SELECT * FROM t3 ORDER BY a+1 LIMIT 3
}
} {1 100 4 2 99 9 3 98 16 sort}
do_test where-6.4 {
cksort {
SELECT * FROM t3 WHERE a<10 ORDER BY a LIMIT 3
}
} {1 100 4 2 99 9 3 98 16 nosort}
do_test where-6.5 {
cksort {
SELECT * FROM t3 WHERE a>0 AND a<10 ORDER BY a LIMIT 3
}
} {1 100 4 2 99 9 3 98 16 nosort}
do_test where-6.6 {
cksort {
SELECT * FROM t3 WHERE a>0 ORDER BY a LIMIT 3
}
} {1 100 4 2 99 9 3 98 16 nosort}
do_test where-6.7 {
cksort {
SELECT * FROM t3 WHERE b>0 ORDER BY a LIMIT 3
}
} {1 100 4 2 99 9 3 98 16 sort}
do_test where-6.8 {
cksort {
SELECT * FROM t3 WHERE a IN (3,5,7,1,9,4,2) ORDER BY a LIMIT 3
}
} {1 100 4 2 99 9 3 98 16 sort}
do_test where-6.9 {
cksort {
SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a LIMIT 3
}
} {1 100 4 nosort}
do_test where-6.10 {
cksort {
SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a LIMIT 3
}
} {1 100 4 nosort}
do_test where-6.11 {
cksort {
SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a,c LIMIT 3
}
} {1 100 4 nosort}
do_test where-6.12 {
cksort {
SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a,c,b LIMIT 3
}
} {1 100 4 nosort}
do_test where-6.13 {
cksort {
SELECT * FROM t3 WHERE a>0 ORDER BY a DESC LIMIT 3
}
} {100 1 10201 99 2 10000 98 3 9801 sort}
do_test where-6.14 {
cksort {
SELECT * FROM t3 ORDER BY b LIMIT 3
}
} {100 1 10201 99 2 10000 98 3 9801 nosort}
do_test where-6.15 {
cksort {
SELECT t3.a, t1.x FROM t3, t1 WHERE t3.a=t1.w ORDER BY t3.a LIMIT 3
}
} {1 0 2 1 3 1 nosort}
do_test where-6.16 {
cksort {
SELECT t3.a, t1.x FROM t3, t1 WHERE t3.a=t1.w ORDER BY t1.x, t3.a LIMIT 3
}
} {1 0 2 1 3 1 sort}
finish_test

View File

@ -25,6 +25,12 @@ proc chng {date desc} {
puts "<DD><P><UL>$desc</UL></P></DD>"
}
chng {2002 Jun 19 (2.5.1)} {
<li>The query optimizer now attempts to implement the ORDER BY clause
using an index. Sorting is still used if not suitable index is
available.</li>
}
chng {2002 Jun 17 (2.5.0)} {
<li>Added support for row triggers.</li>
<li>Added SQL-92 compliant handling of NULLs.</li>