Fix the LIMIT clause so that it applies to the entire query in a compound
query. Prior to this change LIMITs on compound queries did not work at all. Ticket #393. (CVS 1058) FossilOrigin-Name: 543479e3aed77976a0c689cf40811bf88353f706
This commit is contained in:
parent
e5f50722b4
commit
7b58daeafe
20
manifest
20
manifest
@ -1,5 +1,5 @@
|
||||
C Make\ssure\sthe\smin()\sand\smax()\soptimizer\sworks\scorrectly\swhen\sthere\nis\sa\sLIMIT\sclause.\s\sTicket\s#396.\s(CVS\s1057)
|
||||
D 2003-07-19T00:44:14
|
||||
C Fix\sthe\sLIMIT\sclause\sso\sthat\sit\sapplies\sto\sthe\sentire\squery\sin\sa\scompound\nquery.\s\sPrior\sto\sthis\schange\sLIMITs\son\scompound\squeries\sdid\snot\swork\sat\nall.\s\sTicket\s#393.\s(CVS\s1058)
|
||||
D 2003-07-20T01:16:47
|
||||
F Makefile.in 9ad23ed4ca97f9670c4496432e3fbd4b3760ebde
|
||||
F Makefile.linux-gcc b86a99c493a5bfb402d1d9178dcdc4bd4b32f906
|
||||
F README f1de682fbbd94899d50aca13d387d1b3fd3be2dd
|
||||
@ -28,7 +28,7 @@ F src/build.c 13b6ae48ce71a0f59368f548dba2a662375aeaf6
|
||||
F src/copy.c 9e47975ea96751c658bcf1a0c4f0bb7c6ee61e73
|
||||
F src/delete.c 0f81e6799c089487615d38e042a2de4d2d6192bc
|
||||
F src/encode.c 25ea901a9cefb3d93774afa4a06b57cb58acf544
|
||||
F src/expr.c ebdb0f3ee039c8030de25935ce2df030966540a6
|
||||
F src/expr.c 3c07e7b5374649c4921b4ff1287f57d513876c3f
|
||||
F src/func.c 6b23578d48a8be98a664db145a635c2fa9ddb57b
|
||||
F src/hash.c 058f077c1f36f266581aa16f907a3903abf64aa3
|
||||
F src/hash.h cd0433998bc1a3759d244e1637fe5a3c13b53bf8
|
||||
@ -43,11 +43,11 @@ F src/parse.y 16aed0e3ed05445fa7f6a4209cc054208c7083c0
|
||||
F src/pragma.c 3b4f5a800e7a2145bc1930f323232e297d4eb782
|
||||
F src/printf.c 12e45d482ac8abcc6f786fc99e5bed7dd9a51af0
|
||||
F src/random.c 19e8e00fe0df32a742f115773f57651be327cabe
|
||||
F src/select.c f1f3b2c2f4f30db30d03af2d0ec629ef32cb5a08
|
||||
F src/select.c 2fa83d6c972d3e3f379faee32e3621411490dedb
|
||||
F src/shell.c c2ba26c850874964f5ec1ebf6c43406f28e44c4a
|
||||
F src/shell.tcl 27ecbd63dd88396ad16d81ab44f73e6c0ea9d20e
|
||||
F src/sqlite.h.in 54619fa5df4c83b22def66bb3d24808fd03dcbae
|
||||
F src/sqliteInt.h fed31c3e6d21b7a8a38048f8f8a07599360f8946
|
||||
F src/sqliteInt.h e3c756e5aa7bcbf7fbcd20e6aef640c9359c23f2
|
||||
F src/table.c 4301926464d88d2c2c7cd21c3360aa75bf068b95
|
||||
F src/tclsqlite.c d6860dcd56348b9521726280b72c412d2a33ae97
|
||||
F src/test1.c b12b585bfb4763df3262975ed8d3f4f274b5eaed
|
||||
@ -89,7 +89,7 @@ F test/insert2.test c288375a64dad3295044714f0dfed4a193cf067f
|
||||
F test/intpkey.test 9320af48415c594afd4e15f8ef0daa272e05502e
|
||||
F test/ioerr.test 5dbaf09f96b56ee01cf3edd762b96eb4ad2c9ca4
|
||||
F test/join.test 54e770b74fc8cfc7769d5d0bb05657085641b3c4
|
||||
F test/limit.test 87ca391044ae5387cf697f5e3b21acabb03771a3
|
||||
F test/limit.test fa2a8b3fe377ebe60e0bc9a6a35af9ac4eb3d2b3
|
||||
F test/lock.test 388a3a10962d2d571c0c1821cc35bf069ee73473
|
||||
F test/main.test 6a851b5992c4881a725a3d9647e629199df8de9d
|
||||
F test/malloc.test 7ba32a9ebd3aeed52ae4aaa6d42ca37e444536fd
|
||||
@ -158,7 +158,7 @@ F www/faq.tcl 88d3b95d9cd8e374772daa3a646c4d107e7f3e9b
|
||||
F www/fileformat.tcl ae6ccf3ffddb180a5af173cd6ee102169629762b
|
||||
F www/formatchng.tcl ca6cc1cb1bef9bc36f0619049d3c95e749bc6983
|
||||
F www/index.tcl 30adca2dc9aba782f9188c29165129789df521f0
|
||||
F www/lang.tcl 06b825c1e88266866da3a915d0e039249ea2e4e0
|
||||
F www/lang.tcl 5f39bbda1ba38a28f18f97bd98c81f40355393b2
|
||||
F www/mingw.tcl d96b451568c5d28545fefe0c80bee3431c73f69c
|
||||
F www/nulls.tcl 4ac1c9bbb8a20a76500d18d63b383f51bb7d8be7
|
||||
F www/omitted.tcl fe59eaa9c1459cbf08fa7daa83421bfc814331bb
|
||||
@ -168,7 +168,7 @@ F www/speed.tcl 2f6b1155b99d39adb185f900456d1d592c4832b3
|
||||
F www/sqlite.tcl 3c83b08cf9f18aa2d69453ff441a36c40e431604
|
||||
F www/tclsqlite.tcl 1db15abeb446aad0caf0b95b8b9579720e4ea331
|
||||
F www/vdbe.tcl 9b9095d4495f37697fd1935d10e14c6015e80aa1
|
||||
P 558969ee8697180c74308f3f880d3240eb575af1
|
||||
R 90dfb91d095ee0113e81156a9aa2c6cc
|
||||
P c35e50717678703763c696e3e9b265add2ca6454
|
||||
R b4eed2ab716bec174fb746f718cb9bae
|
||||
U drh
|
||||
Z 4035d7869ab09e0fd1a4cac271ac32dd
|
||||
Z 22959393424831715116c486cae1faab
|
||||
|
@ -1 +1 @@
|
||||
c35e50717678703763c696e3e9b265add2ca6454
|
||||
543479e3aed77976a0c689cf40811bf88353f706
|
@ -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.96 2003/05/31 16:21:12 drh Exp $
|
||||
** $Id: expr.c,v 1.97 2003/07/20 01:16:47 drh Exp $
|
||||
*/
|
||||
#include "sqliteInt.h"
|
||||
#include <ctype.h>
|
||||
@ -235,6 +235,8 @@ Select *sqliteSelectDup(Select *p){
|
||||
pNew->nLimit = p->nLimit;
|
||||
pNew->nOffset = p->nOffset;
|
||||
pNew->zSelect = 0;
|
||||
pNew->iLimit = -1;
|
||||
pNew->iOffset = -1;
|
||||
return pNew;
|
||||
}
|
||||
|
||||
|
137
src/select.c
137
src/select.c
@ -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.144 2003/07/19 00:44:14 drh Exp $
|
||||
** $Id: select.c,v 1.145 2003/07/20 01:16:47 drh Exp $
|
||||
*/
|
||||
#include "sqliteInt.h"
|
||||
|
||||
@ -52,6 +52,8 @@ Select *sqliteSelectNew(
|
||||
pNew->op = TK_SELECT;
|
||||
pNew->nLimit = nLimit;
|
||||
pNew->nOffset = nOffset;
|
||||
pNew->iLimit = -1;
|
||||
pNew->iOffset = -1;
|
||||
}
|
||||
return pNew;
|
||||
}
|
||||
@ -450,13 +452,13 @@ static int selectInnerLoop(
|
||||
** to see if this row should be output.
|
||||
*/
|
||||
if( pOrderBy==0 ){
|
||||
if( p->nOffset>0 ){
|
||||
if( p->iOffset>=0 ){
|
||||
int addr = sqliteVdbeCurrentAddr(v);
|
||||
sqliteVdbeAddOp(v, OP_MemIncr, p->nOffset, addr+2);
|
||||
sqliteVdbeAddOp(v, OP_MemIncr, p->iOffset, addr+2);
|
||||
sqliteVdbeAddOp(v, OP_Goto, 0, iContinue);
|
||||
}
|
||||
if( p->nLimit>=0 ){
|
||||
sqliteVdbeAddOp(v, OP_MemIncr, p->nLimit, iBreak);
|
||||
if( p->iLimit>=0 ){
|
||||
sqliteVdbeAddOp(v, OP_MemIncr, p->iLimit, iBreak);
|
||||
}
|
||||
}
|
||||
|
||||
@ -620,13 +622,13 @@ static void generateSortTail(
|
||||
if( eDest==SRT_Sorter ) return;
|
||||
sqliteVdbeAddOp(v, OP_Sort, 0, 0);
|
||||
addr = sqliteVdbeAddOp(v, OP_SortNext, 0, end);
|
||||
if( p->nOffset>0 ){
|
||||
sqliteVdbeAddOp(v, OP_MemIncr, p->nOffset, addr+4);
|
||||
if( p->iOffset>=0 ){
|
||||
sqliteVdbeAddOp(v, OP_MemIncr, p->iOffset, addr+4);
|
||||
sqliteVdbeAddOp(v, OP_Pop, 1, 0);
|
||||
sqliteVdbeAddOp(v, OP_Goto, 0, addr);
|
||||
}
|
||||
if( p->nLimit>=0 ){
|
||||
sqliteVdbeAddOp(v, OP_MemIncr, p->nLimit, end);
|
||||
if( p->iLimit>=0 ){
|
||||
sqliteVdbeAddOp(v, OP_MemIncr, p->iLimit, end);
|
||||
}
|
||||
switch( eDest ){
|
||||
case SRT_Callback: {
|
||||
@ -1244,6 +1246,52 @@ static void multiSelectSortOrder(Select *p, ExprList *pOrderBy){
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
** Compute the iLimit and iOffset fields of the SELECT based on the
|
||||
** nLimit and nOffset fields. nLimit and nOffset hold the integers
|
||||
** that appear in the original SQL statement after the LIMIT and OFFSET
|
||||
** keywords. Or that hold -1 and 0 if those keywords are omitted.
|
||||
** iLimit and iOffset are the integer memory register numbers for
|
||||
** counters used to compute the limit and offset. If there is no
|
||||
** limit and/or offset, then iLimit and iOffset are negative.
|
||||
**
|
||||
** This routine changes the values if iLimit and iOffset only if
|
||||
** a limit or offset is defined by nLimit and nOffset. iLimit and
|
||||
** iOffset should have been preset to appropriate default values
|
||||
** (usually but not always -1) prior to calling this routine.
|
||||
** Only if nLimit>=0 or nOffset>0 do the limit registers get
|
||||
** redefined. The UNION ALL operator uses this property to force
|
||||
** the reuse of the same limit and offset registers across multiple
|
||||
** SELECT statements.
|
||||
*/
|
||||
static void computeLimitRegisters(Parse *pParse, Select *p){
|
||||
/*
|
||||
** If the comparison is p->nLimit>0 then "LIMIT 0" shows
|
||||
** all rows. It is the same as no limit. If the comparision is
|
||||
** p->nLimit>=0 then "LIMIT 0" show no rows at all.
|
||||
** "LIMIT -1" always shows all rows. There is some
|
||||
** contraversy about what the correct behavior should be.
|
||||
** The current implementation interprets "LIMIT 0" to mean
|
||||
** no rows.
|
||||
*/
|
||||
if( p->nLimit>=0 ){
|
||||
int iMem = pParse->nMem++;
|
||||
Vdbe *v = sqliteGetVdbe(pParse);
|
||||
if( v==0 ) return;
|
||||
sqliteVdbeAddOp(v, OP_Integer, -p->nLimit, 0);
|
||||
sqliteVdbeAddOp(v, OP_MemStore, iMem, 1);
|
||||
p->iLimit = iMem;
|
||||
}
|
||||
if( p->nOffset>0 ){
|
||||
int iMem = pParse->nMem++;
|
||||
Vdbe *v = sqliteGetVdbe(pParse);
|
||||
if( v==0 ) return;
|
||||
sqliteVdbeAddOp(v, OP_Integer, -p->nOffset, 0);
|
||||
sqliteVdbeAddOp(v, OP_MemStore, iMem, 1);
|
||||
p->iOffset = iMem;
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
** This routine is called to process a query that is really the union
|
||||
** or intersection of two or more separate queries.
|
||||
@ -1279,8 +1327,8 @@ static int multiSelect(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
Select *pPrior; /* Another SELECT immediately to our left */
|
||||
Vdbe *v; /* Generate code to this VDBE */
|
||||
|
||||
/* Make sure there is no ORDER BY clause on prior SELECTs. Only the
|
||||
** last SELECT in the series may have an ORDER BY.
|
||||
/* Make sure there is no ORDER BY or LIMIT clause on prior SELECTs. Only
|
||||
** the last SELECT in the series may have an ORDER BY or LIMIT.
|
||||
*/
|
||||
if( p==0 || p->pPrior==0 ) return 1;
|
||||
pPrior = p->pPrior;
|
||||
@ -1289,6 +1337,11 @@ static int multiSelect(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
selectOpName(p->op));
|
||||
return 1;
|
||||
}
|
||||
if( pPrior->nLimit>=0 || pPrior->nOffset>0 ){
|
||||
sqliteErrorMsg(pParse,"LIMIT clause should come after %s not before",
|
||||
selectOpName(p->op));
|
||||
return 1;
|
||||
}
|
||||
|
||||
/* Make sure we have a valid query engine. If not, create a new one.
|
||||
*/
|
||||
@ -1307,9 +1360,15 @@ static int multiSelect(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
switch( p->op ){
|
||||
case TK_ALL: {
|
||||
if( p->pOrderBy==0 ){
|
||||
pPrior->nLimit = p->nLimit;
|
||||
pPrior->nOffset = p->nOffset;
|
||||
rc = sqliteSelect(pParse, pPrior, eDest, iParm, 0, 0, 0);
|
||||
if( rc ) return rc;
|
||||
p->pPrior = 0;
|
||||
p->iLimit = pPrior->iLimit;
|
||||
p->iOffset = pPrior->iOffset;
|
||||
p->nLimit = -1;
|
||||
p->nOffset = 0;
|
||||
rc = sqliteSelect(pParse, p, eDest, iParm, 0, 0, 0);
|
||||
p->pPrior = pPrior;
|
||||
if( rc ) return rc;
|
||||
@ -1322,10 +1381,11 @@ static int multiSelect(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
int unionTab; /* Cursor number of the temporary table holding result */
|
||||
int op; /* One of the SRT_ operations to apply to self */
|
||||
int priorOp; /* The SRT_ operation to apply to prior selects */
|
||||
int nLimit, nOffset; /* Saved values of p->nLimit and p->nOffset */
|
||||
ExprList *pOrderBy; /* The ORDER BY clause for the right SELECT */
|
||||
|
||||
priorOp = p->op==TK_ALL ? SRT_Table : SRT_Union;
|
||||
if( eDest==priorOp && p->pOrderBy==0 ){
|
||||
if( eDest==priorOp && p->pOrderBy==0 && p->nLimit<0 && p->nOffset==0 ){
|
||||
/* We can reuse a temporary table generated by a SELECT to our
|
||||
** right.
|
||||
*/
|
||||
@ -1362,9 +1422,15 @@ static int multiSelect(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
p->pPrior = 0;
|
||||
pOrderBy = p->pOrderBy;
|
||||
p->pOrderBy = 0;
|
||||
nLimit = p->nLimit;
|
||||
p->nLimit = -1;
|
||||
nOffset = p->nOffset;
|
||||
p->nOffset = 0;
|
||||
rc = sqliteSelect(pParse, p, op, unionTab, 0, 0, 0);
|
||||
p->pPrior = pPrior;
|
||||
p->pOrderBy = pOrderBy;
|
||||
p->nLimit = nLimit;
|
||||
p->nOffset = nOffset;
|
||||
if( rc ) return rc;
|
||||
|
||||
/* Convert the data in the temporary table into whatever form
|
||||
@ -1380,6 +1446,7 @@ static int multiSelect(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
iBreak = sqliteVdbeMakeLabel(v);
|
||||
iCont = sqliteVdbeMakeLabel(v);
|
||||
sqliteVdbeAddOp(v, OP_Rewind, unionTab, iBreak);
|
||||
computeLimitRegisters(pParse, p);
|
||||
iStart = sqliteVdbeCurrentAddr(v);
|
||||
multiSelectSortOrder(p, p->pOrderBy);
|
||||
rc = selectInnerLoop(pParse, p, p->pEList, unionTab, p->pEList->nExpr,
|
||||
@ -1399,6 +1466,7 @@ static int multiSelect(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
case TK_INTERSECT: {
|
||||
int tab1, tab2;
|
||||
int iCont, iBreak, iStart;
|
||||
int nLimit, nOffset;
|
||||
|
||||
/* INTERSECT is different from the others since it requires
|
||||
** two temporary tables. Hence it has its own case. Begin
|
||||
@ -1422,8 +1490,14 @@ static int multiSelect(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
sqliteVdbeAddOp(v, OP_OpenTemp, tab2, 1);
|
||||
sqliteVdbeAddOp(v, OP_KeyAsData, tab2, 1);
|
||||
p->pPrior = 0;
|
||||
nLimit = p->nLimit;
|
||||
p->nLimit = -1;
|
||||
nOffset = p->nOffset;
|
||||
p->nOffset = 0;
|
||||
rc = sqliteSelect(pParse, p, SRT_Union, tab2, 0, 0, 0);
|
||||
p->pPrior = pPrior;
|
||||
p->nLimit = nLimit;
|
||||
p->nOffset = nOffset;
|
||||
if( rc ) return rc;
|
||||
|
||||
/* Generate code to take the intersection of the two temporary
|
||||
@ -1437,6 +1511,7 @@ static int multiSelect(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
iBreak = sqliteVdbeMakeLabel(v);
|
||||
iCont = sqliteVdbeMakeLabel(v);
|
||||
sqliteVdbeAddOp(v, OP_Rewind, tab1, iBreak);
|
||||
computeLimitRegisters(pParse, p);
|
||||
iStart = sqliteVdbeAddOp(v, OP_FullKey, tab1, 0);
|
||||
sqliteVdbeAddOp(v, OP_NotFound, tab2, iCont);
|
||||
multiSelectSortOrder(p, p->pOrderBy);
|
||||
@ -1869,6 +1944,7 @@ static int simpleMinMaxQuery(Parse *pParse, Select *p, int eDest, int iParm){
|
||||
*/
|
||||
sqliteCodeVerifySchema(pParse, pTab->iDb);
|
||||
base = p->pSrc->a[0].iCursor;
|
||||
computeLimitRegisters(pParse, p);
|
||||
sqliteVdbeAddOp(v, OP_Integer, pTab->iDb, 0);
|
||||
sqliteVdbeAddOp(v, OP_OpenRead, base, pTab->tnum);
|
||||
sqliteVdbeChangeP3(v, -1, pTab->zName, P3_STATIC);
|
||||
@ -2132,39 +2208,6 @@ int sqliteSelect(
|
||||
generateColumnNames(pParse, pTabList, pEList);
|
||||
}
|
||||
|
||||
/* Set the limiter.
|
||||
**
|
||||
** The phrase "LIMIT 0" means all rows are shown, not zero rows.
|
||||
** If the comparison is p->nLimit<=0 then "LIMIT 0" shows
|
||||
** all rows. It is the same as no limit. If the comparision is
|
||||
** p->nLimit<0 then "LIMIT 0" show no rows at all.
|
||||
** "LIMIT -1" always shows all rows. There is some
|
||||
** contraversy about what the correct behavior should be.
|
||||
**
|
||||
** Note that up until this point, the nLimit and nOffset hold
|
||||
** the numeric values of the limit and offset that appeared in
|
||||
** the original SQL. After this code, the nLimit and nOffset hold
|
||||
** the register number of counters used to track the limit and
|
||||
** offset.
|
||||
*/
|
||||
if( p->nLimit<0 ){
|
||||
p->nLimit = -1;
|
||||
}else{
|
||||
int iMem = pParse->nMem++;
|
||||
sqliteVdbeAddOp(v, OP_Integer, -p->nLimit, 0);
|
||||
sqliteVdbeAddOp(v, OP_MemStore, iMem, 1);
|
||||
p->nLimit = iMem;
|
||||
}
|
||||
if( p->nOffset<=0 ){
|
||||
p->nOffset = 0;
|
||||
}else{
|
||||
int iMem = pParse->nMem++;
|
||||
if( iMem==0 ) iMem = pParse->nMem++;
|
||||
sqliteVdbeAddOp(v, OP_Integer, -p->nOffset, 0);
|
||||
sqliteVdbeAddOp(v, OP_MemStore, iMem, 1);
|
||||
p->nOffset = iMem;
|
||||
}
|
||||
|
||||
/* Check for the special case of a min() or max() function by itself
|
||||
** in the result set.
|
||||
*/
|
||||
@ -2211,6 +2254,10 @@ int sqliteSelect(
|
||||
return rc;
|
||||
}
|
||||
|
||||
/* Set the limiter.
|
||||
*/
|
||||
computeLimitRegisters(pParse, p);
|
||||
|
||||
/* Identify column types if we will be using a callback. This
|
||||
** step is skipped if the output is going to a destination other
|
||||
** than a callback.
|
||||
|
@ -11,7 +11,7 @@
|
||||
*************************************************************************
|
||||
** Internal interface definitions for SQLite.
|
||||
**
|
||||
** @(#) $Id: sqliteInt.h,v 1.193 2003/06/23 11:06:02 drh Exp $
|
||||
** @(#) $Id: sqliteInt.h,v 1.194 2003/07/20 01:16:47 drh Exp $
|
||||
*/
|
||||
#include "config.h"
|
||||
#include "sqlite.h"
|
||||
@ -778,16 +778,17 @@ struct WhereInfo {
|
||||
** in the VDBE that record the limit and offset counters.
|
||||
*/
|
||||
struct Select {
|
||||
int isDistinct; /* True if the DISTINCT keyword is present */
|
||||
ExprList *pEList; /* The fields of the result */
|
||||
u8 op; /* One of: TK_UNION TK_ALL TK_INTERSECT TK_EXCEPT */
|
||||
u8 isDistinct; /* True if the DISTINCT keyword is present */
|
||||
SrcList *pSrc; /* The FROM clause */
|
||||
Expr *pWhere; /* The WHERE clause */
|
||||
ExprList *pGroupBy; /* The GROUP BY clause */
|
||||
Expr *pHaving; /* The HAVING clause */
|
||||
ExprList *pOrderBy; /* The ORDER BY clause */
|
||||
int op; /* One of: TK_UNION TK_ALL TK_INTERSECT TK_EXCEPT */
|
||||
Select *pPrior; /* Prior select in a compound select statement */
|
||||
int nLimit, nOffset; /* LIMIT and OFFSET values. -1 means not used */
|
||||
int iLimit, iOffset; /* Memory registers holding LIMIT & OFFSET counters */
|
||||
char *zSelect; /* Complete text of the SELECT command */
|
||||
};
|
||||
|
||||
|
@ -12,7 +12,7 @@
|
||||
# focus of this file is testing the LIMIT ... OFFSET ... clause
|
||||
# of SELECT statements.
|
||||
#
|
||||
# $Id: limit.test,v 1.9 2003/07/16 11:51:36 drh Exp $
|
||||
# $Id: limit.test,v 1.10 2003/07/20 01:16:48 drh Exp $
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
@ -213,4 +213,84 @@ do_test limit-6.8 {
|
||||
}
|
||||
} {}
|
||||
|
||||
# Make sure LIMIT works well with compound SELECT statements.
|
||||
# Ticket #393
|
||||
#
|
||||
do_test limit-7.1.1 {
|
||||
catchsql {
|
||||
SELECT x FROM t2 LIMIT 5 UNION ALL SELECT a FROM t6;
|
||||
}
|
||||
} {1 {LIMIT clause should come after UNION ALL not before}}
|
||||
do_test limit-7.1.2 {
|
||||
catchsql {
|
||||
SELECT x FROM t2 LIMIT 5 UNION SELECT a FROM t6;
|
||||
}
|
||||
} {1 {LIMIT clause should come after UNION not before}}
|
||||
do_test limit-7.1.3 {
|
||||
catchsql {
|
||||
SELECT x FROM t2 LIMIT 5 EXCEPT SELECT a FROM t6 LIMIT 3;
|
||||
}
|
||||
} {1 {LIMIT clause should come after EXCEPT not before}}
|
||||
do_test limit-7.1.4 {
|
||||
catchsql {
|
||||
SELECT x FROM t2 LIMIT 0,5 INTERSECT SELECT a FROM t6;
|
||||
}
|
||||
} {1 {LIMIT clause should come after INTERSECT not before}}
|
||||
do_test limit-7.2 {
|
||||
execsql {
|
||||
SELECT x FROM t2 UNION ALL SELECT a FROM t6 LIMIT 5;
|
||||
}
|
||||
} {31 30 1 2 3}
|
||||
do_test limit-7.3 {
|
||||
execsql {
|
||||
SELECT x FROM t2 UNION ALL SELECT a FROM t6 LIMIT 3 OFFSET 1;
|
||||
}
|
||||
} {30 1 2}
|
||||
do_test limit-7.4 {
|
||||
execsql {
|
||||
SELECT x FROM t2 UNION ALL SELECT a FROM t6 ORDER BY 1 LIMIT 3 OFFSET 1;
|
||||
}
|
||||
} {2 3 4}
|
||||
do_test limit-7.5 {
|
||||
execsql {
|
||||
SELECT x FROM t2 UNION SELECT x+2 FROM t2 LIMIT 2 OFFSET 1;
|
||||
}
|
||||
} {31 32}
|
||||
do_test limit-7.6 {
|
||||
execsql {
|
||||
SELECT x FROM t2 UNION SELECT x+2 FROM t2 ORDER BY 1 DESC LIMIT 2 OFFSET 1;
|
||||
}
|
||||
} {32 31}
|
||||
do_test limit-7.7 {
|
||||
execsql {
|
||||
SELECT a+9 FROM t6 EXCEPT SELECT y FROM t2 LIMIT 2;
|
||||
}
|
||||
} {11 12}
|
||||
do_test limit-7.8 {
|
||||
execsql {
|
||||
SELECT a+9 FROM t6 EXCEPT SELECT y FROM t2 ORDER BY 1 DESC LIMIT 2;
|
||||
}
|
||||
} {13 12}
|
||||
do_test limit-7.9 {
|
||||
execsql {
|
||||
SELECT a+26 FROM t6 INTERSECT SELECT x FROM t2 LIMIT 1;
|
||||
}
|
||||
} {30}
|
||||
do_test limit-7.10 {
|
||||
execsql {
|
||||
SELECT a+27 FROM t6 INTERSECT SELECT x FROM t2 LIMIT 1;
|
||||
}
|
||||
} {30}
|
||||
do_test limit-7.11 {
|
||||
execsql {
|
||||
SELECT a+27 FROM t6 INTERSECT SELECT x FROM t2 LIMIT 1 OFFSET 1;
|
||||
}
|
||||
} {31}
|
||||
do_test limit-7.12 {
|
||||
execsql {
|
||||
SELECT a+27 FROM t6 INTERSECT SELECT x FROM t2
|
||||
ORDER BY 1 DESC LIMIT 1 OFFSET 1;
|
||||
}
|
||||
} {30}
|
||||
|
||||
finish_test
|
||||
|
@ -1,7 +1,7 @@
|
||||
#
|
||||
# Run this Tcl script to generate the sqlite.html file.
|
||||
#
|
||||
set rcsid {$Id: lang.tcl,v 1.64 2003/07/16 11:51:36 drh Exp $}
|
||||
set rcsid {$Id: lang.tcl,v 1.65 2003/07/20 01:16:48 drh Exp $}
|
||||
|
||||
puts {<html>
|
||||
<head>
|
||||
@ -1552,7 +1552,12 @@ the sort order.</p>
|
||||
<p>The LIMIT clause places an upper bound on the number of rows
|
||||
returned in the result. A negative LIMIT indicates no upper bound.
|
||||
The optional OFFSET following LIMIT specifies how many
|
||||
rows to skip at the beginning of the result set.</p>
|
||||
rows to skip at the beginning of the result set.
|
||||
In a compound query, the LIMIT clause may only appear on the
|
||||
final SELECT statement.
|
||||
The limit is applied to the entire query not
|
||||
to the individual SELECT statement to which it is attached.
|
||||
</p>
|
||||
|
||||
<p>A compound SELECT is formed from two or more simple SELECTs connected
|
||||
by one of the operators UNION, UNION ALL, INTERSECT, or EXCEPT. In
|
||||
|
Loading…
x
Reference in New Issue
Block a user