Enhance recursive common table expressions to support two or more

recursive terms.

FossilOrigin-Name: 77e64647ec429c6e0d884abbd00dabebe738f89544a4984d6fd7a702b928ccfd
This commit is contained in:
drh 2020-10-19 12:35:08 +00:00
commit 787f6d418d
7 changed files with 2149 additions and 42 deletions

1895
manifest

File diff suppressed because it is too large Load Diff

View File

@ -1 +1 @@
7f8802bb7be61fdf7c7a591945d533d848bc46d2989f7739dd9ad89e1b6a9c65
77e64647ec429c6e0d884abbd00dabebe738f89544a4984d6fd7a702b928ccfd

View File

@ -4460,7 +4460,7 @@ void sqlite3SrcListAssignCursors(Parse *pParse, SrcList *pList){
assert(pList || pParse->db->mallocFailed );
if( pList ){
for(i=0, pItem=pList->a; i<pList->nSrc; i++, pItem++){
if( pItem->iCursor>=0 ) break;
if( pItem->iCursor>=0 ) continue;
pItem->iCursor = pParse->nTab++;
if( pItem->pSelect ){
sqlite3SrcListAssignCursors(pParse, pItem->pSelect->pSrc);

View File

@ -2340,6 +2340,7 @@ static void generateWithRecursiveQuery(
int nCol = p->pEList->nExpr; /* Number of columns in the recursive table */
Vdbe *v = pParse->pVdbe; /* The prepared statement under construction */
Select *pSetup = p->pPrior; /* The setup query */
Select *pFirstRec; /* Left-most recursive term */
int addrTop; /* Top of the loop */
int addrCont, addrBreak; /* CONTINUE and BREAK addresses */
int iCurrent = 0; /* The Current table */
@ -2415,7 +2416,25 @@ static void generateWithRecursiveQuery(
/* Detach the ORDER BY clause from the compound SELECT */
p->pOrderBy = 0;
/* Figure out how many elements of the compound SELECT are part of the
** recursive query. Make sure no recursive elements use aggregate
** functions. Mark the recursive elements as UNION ALL even if they
** are really UNION because the distinctness will be enforced by the
** iDistinct table. pFirstRec is left pointing to the left-most
** recursive term of the CTE.
*/
pFirstRec = p;
for(pFirstRec=p; ALWAYS(pFirstRec!=0); pFirstRec=pFirstRec->pPrior){
if( pFirstRec->selFlags & SF_Aggregate ){
sqlite3ErrorMsg(pParse, "recursive aggregate queries not supported");
goto end_of_recursive_query;
}
pFirstRec->op = TK_ALL;
if( (pFirstRec->pPrior->selFlags & SF_Recursive)==0 ) break;
}
/* Store the results of the setup-query in Queue. */
pSetup = pFirstRec->pPrior;
pSetup->pNext = 0;
ExplainQueryPlan((pParse, 1, "SETUP"));
rc = sqlite3Select(pParse, pSetup, &destQueue);
@ -2448,15 +2467,11 @@ static void generateWithRecursiveQuery(
/* Execute the recursive SELECT taking the single row in Current as
** the value for the recursive-table. Store the results in the Queue.
*/
if( p->selFlags & SF_Aggregate ){
sqlite3ErrorMsg(pParse, "recursive aggregate queries not supported");
}else{
p->pPrior = 0;
ExplainQueryPlan((pParse, 1, "RECURSIVE STEP"));
sqlite3Select(pParse, p, &destQueue);
assert( p->pPrior==0 );
p->pPrior = pSetup;
}
pFirstRec->pPrior = 0;
ExplainQueryPlan((pParse, 1, "RECURSIVE STEP"));
sqlite3Select(pParse, p, &destQueue);
assert( pFirstRec->pPrior==0 );
pFirstRec->pPrior = pSetup;
/* Keep running the loop until the Queue is empty */
sqlite3VdbeGoto(v, addrTop);
@ -2525,6 +2540,16 @@ static int multiSelectValues(
return rc;
}
/*
** Return true if the SELECT statement which is known to be the recursive
** part of a recursive CTE still has its anchor terms attached. If the
** anchor terms have already been removed, then return false.
*/
static int hasAnchor(Select *p){
while( p && (p->selFlags & SF_Recursive)!=0 ){ p = p->pPrior; }
return p!=0;
}
/*
** This routine is called to process a compound query form from
** two or more separate queries using UNION, UNION ALL, EXCEPT, or
@ -2610,7 +2635,7 @@ static int multiSelect(
assert( p->pEList->nExpr==pPrior->pEList->nExpr );
#ifndef SQLITE_OMIT_CTE
if( p->selFlags & SF_Recursive ){
if( (p->selFlags & SF_Recursive)!=0 && hasAnchor(p) ){
generateWithRecursiveQuery(pParse, p, &dest);
}else
#endif
@ -2701,6 +2726,7 @@ static int multiSelect(
findRightmost(p)->selFlags |= SF_UsesEphemeral;
assert( p->pEList );
}
/* Code the SELECT statements to our left
*/
@ -4794,8 +4820,10 @@ static int withExpand(
ExprList *pEList;
Select *pSel;
Select *pLeft; /* Left-most SELECT statement */
Select *pRecTerm; /* Left-most recursive term */
int bMayRecursive; /* True if compound joined by UNION [ALL] */
With *pSavedWith; /* Initial value of pParse->pWith */
int iRecTab = -1; /* Cursor for recursive table */
/* If pCte->zCteErr is non-NULL at this point, then this is an illegal
** recursive reference to CTE pCte. Leave an error in pParse and return
@ -4820,44 +4848,48 @@ static int withExpand(
assert( pFrom->pSelect );
/* Check if this is a recursive CTE. */
pSel = pFrom->pSelect;
pRecTerm = pSel = pFrom->pSelect;
bMayRecursive = ( pSel->op==TK_ALL || pSel->op==TK_UNION );
if( bMayRecursive ){
while( bMayRecursive && pRecTerm->op==pSel->op ){
int i;
SrcList *pSrc = pFrom->pSelect->pSrc;
SrcList *pSrc = pRecTerm->pSrc;
assert( pRecTerm->pPrior!=0 );
for(i=0; i<pSrc->nSrc; i++){
struct SrcList_item *pItem = &pSrc->a[i];
if( pItem->zDatabase==0
&& pItem->zName!=0
&& 0==sqlite3StrICmp(pItem->zName, pCte->zName)
){
){
pItem->pTab = pTab;
pItem->fg.isRecursive = 1;
if( pRecTerm->selFlags & SF_Recursive ){
sqlite3ErrorMsg(pParse,
"multiple references to recursive table: %s", pCte->zName
);
return SQLITE_ERROR;
}
pTab->nTabRef++;
pSel->selFlags |= SF_Recursive;
pRecTerm->selFlags |= SF_Recursive;
if( iRecTab<0 ) iRecTab = pParse->nTab++;
pItem->iCursor = iRecTab;
}
}
if( (pRecTerm->selFlags & SF_Recursive)==0 ) break;
pRecTerm = pRecTerm->pPrior;
}
/* Only one recursive reference is permitted. */
if( pTab->nTabRef>2 ){
sqlite3ErrorMsg(
pParse, "multiple references to recursive table: %s", pCte->zName
);
return SQLITE_ERROR;
}
assert( pTab->nTabRef==1 ||
((pSel->selFlags&SF_Recursive) && pTab->nTabRef==2 ));
pCte->zCteErr = "circular reference: %s";
pSavedWith = pParse->pWith;
pParse->pWith = pWith;
if( bMayRecursive ){
Select *pPrior = pSel->pPrior;
assert( pPrior->pWith==0 );
pPrior->pWith = pSel->pWith;
sqlite3WalkSelect(pWalker, pPrior);
pPrior->pWith = 0;
if( pSel->selFlags & SF_Recursive ){
assert( pRecTerm!=0 );
assert( (pRecTerm->selFlags & SF_Recursive)==0 );
assert( pRecTerm->pNext!=0 );
assert( (pRecTerm->pNext->selFlags & SF_Recursive)!=0 );
assert( pRecTerm->pWith==0 );
pRecTerm->pWith = pSel->pWith;
sqlite3WalkSelect(pWalker, pRecTerm);
pRecTerm->pWith = 0;
}else{
sqlite3WalkSelect(pWalker, pSel);
}

View File

@ -352,7 +352,7 @@ do_catchsql_test 7.4 {
SELECT i FROM tree WHERE p IN (SELECT id FROM t)
)
SELECT id FROM t;
} {1 {recursive reference in a subquery: t}}
} {1 {circular reference: t}}
do_catchsql_test 7.5 {
WITH t(id) AS (

View File

@ -30,7 +30,7 @@ do_catchsql_test 1.0 {
SELECT 5 FROM t0 UNION SELECT 8 FROM m
)
SELECT * FROM i;
} {1 {no such table: t0}}
} {1 {no such table: m}}
# 2019-11-09 dbfuzzcheck find
do_catchsql_test 1.1 {

194
test/with5.test Normal file
View File

@ -0,0 +1,194 @@
# 2020-10-19
#
# 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 recursive common table expressions with
# multiple recursive terms in the compound select.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
set ::testprefix with5
ifcapable {!cte} {
finish_test
return
}
do_execsql_test 100 {
CREATE TABLE link(aa INT, bb INT);
CREATE INDEX link_f ON link(aa,bb);
CREATE INDEX link_t ON link(bb,aa);
INSERT INTO link(aa,bb) VALUES
(1,3),
(5,3),
(7,1),
(7,9),
(9,9),
(5,11),
(11,7),
(2,4),
(4,6),
(8,6);
} {}
do_execsql_test 110 {
WITH RECURSIVE closure(x) AS (
VALUES(1)
UNION
SELECT aa FROM closure, link WHERE link.bb=closure.x
UNION
SELECT bb FROM closure, link WHERE link.aa=closure.x
)
SELECT x FROM closure ORDER BY x;
} {1 3 5 7 9 11}
do_execsql_test 111 {
WITH RECURSIVE closure(x) AS (
VALUES(1)
UNION
SELECT aa FROM link, closure WHERE link.bb=closure.x
UNION
SELECT bb FROM closure, link WHERE link.aa=closure.x
)
SELECT x FROM closure ORDER BY x;
} {1 3 5 7 9 11}
do_execsql_test 112 {
WITH RECURSIVE closure(x) AS (
VALUES(1)
UNION
SELECT bb FROM closure, link WHERE link.aa=closure.x
UNION
SELECT aa FROM link, closure WHERE link.bb=closure.x
)
SELECT x FROM closure ORDER BY x;
} {1 3 5 7 9 11}
do_execsql_test 113 {
WITH RECURSIVE closure(x) AS (
VALUES(1),(200),(300),(400)
INTERSECT
VALUES(1)
UNION
SELECT bb FROM closure, link WHERE link.aa=closure.x
UNION
SELECT aa FROM link, closure WHERE link.bb=closure.x
)
SELECT x FROM closure ORDER BY x;
} {1 3 5 7 9 11}
do_execsql_test 114 {
WITH RECURSIVE closure(x) AS (
VALUES(1),(200),(300),(400)
UNION ALL
VALUES(2)
UNION
SELECT bb FROM closure, link WHERE link.aa=closure.x
UNION
SELECT aa FROM link, closure WHERE link.bb=closure.x
)
SELECT x FROM closure ORDER BY x;
} {1 2 3 4 5 6 7 8 9 11 200 300 400}
do_catchsql_test 120 {
WITH RECURSIVE closure(x) AS (
VALUES(1),(200),(300),(400)
UNION ALL
VALUES(2)
UNION ALL
SELECT bb FROM closure, link WHERE link.aa=closure.x
UNION
SELECT aa FROM link, closure WHERE link.bb=closure.x
)
SELECT x FROM closure ORDER BY x;
} {1 {circular reference: closure}}
do_catchsql_test 121 {
WITH RECURSIVE closure(x) AS (
VALUES(1),(200),(300),(400)
UNION ALL
VALUES(2)
UNION
SELECT bb FROM closure, link WHERE link.aa=closure.x
UNION ALL
SELECT aa FROM link, closure WHERE link.bb=closure.x
)
SELECT x FROM closure ORDER BY x;
} {1 {circular reference: closure}}
do_execsql_test 130 {
WITH RECURSIVE closure(x) AS (
SELECT 1 AS x
UNION
SELECT aa FROM link JOIN closure ON bb=x
UNION
SELECT bb FROM link JOIN closure on aa=x
ORDER BY x LIMIT 4
)
SELECT * FROM closure;
} {1 3 5 7}
do_execsql_test 131 {
WITH RECURSIVE closure(x) AS (
SELECT 1 AS x
UNION ALL
SELECT 2
UNION
SELECT aa FROM link JOIN closure ON bb=x
UNION
SELECT bb FROM link JOIN closure on aa=x
ORDER BY x LIMIT 4
)
SELECT * FROM closure;
} {1 2 3 4}
do_execsql_test 200 {
CREATE TABLE linkA(aa1,aa2);
INSERT INTO linkA(aa1,aa2) VALUES(1,3),(5,7),(9,11);
CREATE TABLE linkB(bb1,bb2);
INSERT INTO linkB(bb1,bb2) VALUES(7,9),(11,13),(3,5);
CREATE TABLE linkC(cc1,cc2);
INSERT INTO linkC(cc1,cc2) VALUES(1,2),(2,4),(6,8);
CREATE TABLE linkD(dd1,dd2);
INSERT INTO linkD(dd1,dd2) VALUES(4,6),(100,110);
} {}
do_execsql_test 210 {
WITH RECURSIVE closure(x) AS (
VALUES(1)
UNION ALL
SELECT aa2 FROM linkA JOIN closure ON x=aa1
UNION ALL
SELECT bb2 FROM linkB JOIN closure ON x=bb1
UNION ALL
SELECT cc2 FROM linkC JOIN closure ON x=cc1
UNION ALL
SELECT dd2 FROM linkD JOIN closure ON x=dd1
)
SELECT x FROM closure ORDER BY +x;
} {1 2 3 4 5 6 7 8 9 11 13}
do_execsql_test 220 {
CREATE TABLE linkA_ipk(aa1 INTEGER PRIMARY KEY,aa2);
INSERT INTO linkA_ipk(aa1,aa2) SELECT aa1, aa2 FROM linkA;
CREATE TABLE linkB_ipk(bb1 INTEGER PRIMARY KEY,bb2);
INSERT INTO linkB_ipk(bb1,bb2) SELECT bb1, bb2 FROM linkB;
CREATE TABLE linkC_ipk(cc1 INTEGER PRIMARY KEY,cc2);
INSERT INTO linkC_ipk(cc1,cc2) SELECT cc1, cc2 FROM linkC;
CREATE TABLE linkD_ipk(dd1 INTEGER PRIMARY KEY,dd2);
INSERT INTO linkD_ipk(dd1,dd2) SELECT dd1, dd2 FROM linkD;
WITH RECURSIVE closure(x) AS (
VALUES(1)
UNION ALL
SELECT aa2 FROM linkA_ipk JOIN closure ON x=aa1
UNION ALL
SELECT bb2 FROM linkB_ipk JOIN closure ON x=bb1
UNION ALL
SELECT cc2 FROM linkC_ipk JOIN closure ON x=cc1
UNION ALL
SELECT dd2 FROM linkD_ipk JOIN closure ON x=dd1
)
SELECT x FROM closure ORDER BY +x;
} {1 2 3 4 5 6 7 8 9 11 13}
finish_test