Index: src/func.c ================================================================== --- src/func.c +++ src/func.c @@ -2158,15 +2158,15 @@ FUNCTION(trim, 1, 3, 0, trimFunc ), FUNCTION(trim, 2, 3, 0, trimFunc ), FUNCTION(min, -1, 0, 1, minmaxFunc ), FUNCTION(min, 0, 0, 1, 0 ), WAGGREGATE(min, 1, 0, 1, minmaxStep, minMaxFinalize, minMaxValue, 0, - SQLITE_FUNC_MINMAX ), + SQLITE_FUNC_MINMAX|SQLITE_FUNC_ANYORDER ), FUNCTION(max, -1, 1, 1, minmaxFunc ), FUNCTION(max, 0, 1, 1, 0 ), WAGGREGATE(max, 1, 1, 1, minmaxStep, minMaxFinalize, minMaxValue, 0, - SQLITE_FUNC_MINMAX ), + SQLITE_FUNC_MINMAX|SQLITE_FUNC_ANYORDER ), FUNCTION2(typeof, 1, 0, 0, typeofFunc, SQLITE_FUNC_TYPEOF), FUNCTION2(length, 1, 0, 0, lengthFunc, SQLITE_FUNC_LENGTH), FUNCTION(instr, 2, 0, 0, instrFunc ), FUNCTION(printf, -1, 0, 0, printfFunc ), FUNCTION(unicode, 1, 0, 0, unicodeFunc ), @@ -2198,13 +2198,14 @@ FUNCTION(substring, 3, 0, 0, substrFunc ), WAGGREGATE(sum, 1,0,0, sumStep, sumFinalize, sumFinalize, sumInverse, 0), WAGGREGATE(total, 1,0,0, sumStep,totalFinalize,totalFinalize,sumInverse, 0), WAGGREGATE(avg, 1,0,0, sumStep, avgFinalize, avgFinalize, sumInverse, 0), WAGGREGATE(count, 0,0,0, countStep, - countFinalize, countFinalize, countInverse, SQLITE_FUNC_COUNT ), + countFinalize, countFinalize, countInverse, + SQLITE_FUNC_COUNT|SQLITE_FUNC_ANYORDER ), WAGGREGATE(count, 1,0,0, countStep, - countFinalize, countFinalize, countInverse, 0 ), + countFinalize, countFinalize, countInverse, SQLITE_FUNC_ANYORDER ), WAGGREGATE(group_concat, 1, 0, 0, groupConcatStep, groupConcatFinalize, groupConcatValue, groupConcatInverse, 0), WAGGREGATE(group_concat, 2, 0, 0, groupConcatStep, groupConcatFinalize, groupConcatValue, groupConcatInverse, 0), Index: src/resolve.c ================================================================== --- src/resolve.c +++ src/resolve.c @@ -1085,13 +1085,16 @@ pNC2 = pNC2->pNext; } assert( pDef!=0 || IN_RENAME_OBJECT ); if( pNC2 && pDef ){ assert( SQLITE_FUNC_MINMAX==NC_MinMaxAgg ); + assert( SQLITE_FUNC_ANYORDER==NC_OrderAgg ); testcase( (pDef->funcFlags & SQLITE_FUNC_MINMAX)!=0 ); - pNC2->ncFlags |= NC_HasAgg | (pDef->funcFlags & SQLITE_FUNC_MINMAX); - + testcase( (pDef->funcFlags & SQLITE_FUNC_ANYORDER)!=0 ); + pNC2->ncFlags |= NC_HasAgg + | ((pDef->funcFlags^SQLITE_FUNC_ANYORDER) + & (SQLITE_FUNC_MINMAX|SQLITE_FUNC_ANYORDER)); } } pNC->ncFlags |= savedAllowFlags; } /* FIX ME: Compute pExpr->affinity based on the expected return @@ -1630,11 +1633,11 @@ assert( pSub->pPrior && pSub->pOrderBy==0 ); pSub->pOrderBy = p->pOrderBy; p->pOrderBy = 0; } - /* Recursively resolve names in all subqueries + /* Recursively resolve names in all subqueries in the FROM clause */ for(i=0; ipSrc->nSrc; i++){ SrcItem *pItem = &p->pSrc->a[i]; if( pItem->pSelect && (pItem->pSelect->selFlags & SF_Resolved)==0 ){ int nRef = pOuterNC ? pOuterNC->nRef : 0; @@ -1674,11 +1677,12 @@ */ assert( (p->selFlags & SF_Aggregate)==0 ); pGroupBy = p->pGroupBy; if( pGroupBy || (sNC.ncFlags & NC_HasAgg)!=0 ){ assert( NC_MinMaxAgg==SF_MinMaxAgg ); - p->selFlags |= SF_Aggregate | (sNC.ncFlags&NC_MinMaxAgg); + assert( NC_OrderAgg==SF_OrderByReqd ); + p->selFlags |= SF_Aggregate | (sNC.ncFlags&(NC_MinMaxAgg|NC_OrderAgg)); }else{ sNC.ncFlags &= ~NC_AllowAgg; } /* Add the output column list to the name-context before parsing the @@ -1857,12 +1861,12 @@ ){ int savedHasAgg; Walker w; if( pExpr==0 ) return SQLITE_OK; - savedHasAgg = pNC->ncFlags & (NC_HasAgg|NC_MinMaxAgg|NC_HasWin); - pNC->ncFlags &= ~(NC_HasAgg|NC_MinMaxAgg|NC_HasWin); + savedHasAgg = pNC->ncFlags & (NC_HasAgg|NC_MinMaxAgg|NC_HasWin|NC_OrderAgg); + pNC->ncFlags &= ~(NC_HasAgg|NC_MinMaxAgg|NC_HasWin|NC_OrderAgg); w.pParse = pNC->pParse; w.xExprCallback = resolveExprStep; w.xSelectCallback = (pNC->ncFlags & NC_NoSelect) ? 0 : resolveSelectStep; w.xSelectCallback2 = 0; w.u.pNC = pNC; @@ -1901,12 +1905,12 @@ w.pParse = pNC->pParse; w.xExprCallback = resolveExprStep; w.xSelectCallback = resolveSelectStep; w.xSelectCallback2 = 0; w.u.pNC = pNC; - savedHasAgg = pNC->ncFlags & (NC_HasAgg|NC_MinMaxAgg|NC_HasWin); - pNC->ncFlags &= ~(NC_HasAgg|NC_MinMaxAgg|NC_HasWin); + savedHasAgg = pNC->ncFlags & (NC_HasAgg|NC_MinMaxAgg|NC_HasWin|NC_OrderAgg); + pNC->ncFlags &= ~(NC_HasAgg|NC_MinMaxAgg|NC_HasWin|NC_OrderAgg); for(i=0; inExpr; i++){ Expr *pExpr = pList->a[i].pExpr; if( pExpr==0 ) continue; #if SQLITE_MAX_EXPR_DEPTH>0 w.pParse->nHeight += pExpr->nHeight; @@ -1920,14 +1924,15 @@ #endif assert( EP_Agg==NC_HasAgg ); assert( EP_Win==NC_HasWin ); testcase( pNC->ncFlags & NC_HasAgg ); testcase( pNC->ncFlags & NC_HasWin ); - if( pNC->ncFlags & (NC_HasAgg|NC_MinMaxAgg|NC_HasWin) ){ + if( pNC->ncFlags & (NC_HasAgg|NC_MinMaxAgg|NC_HasWin|NC_OrderAgg) ){ ExprSetProperty(pExpr, pNC->ncFlags & (NC_HasAgg|NC_HasWin) ); - savedHasAgg |= pNC->ncFlags & (NC_HasAgg|NC_MinMaxAgg|NC_HasWin); - pNC->ncFlags &= ~(NC_HasAgg|NC_MinMaxAgg|NC_HasWin); + savedHasAgg |= pNC->ncFlags & + (NC_HasAgg|NC_MinMaxAgg|NC_HasWin|NC_OrderAgg); + pNC->ncFlags &= ~(NC_HasAgg|NC_MinMaxAgg|NC_HasWin|NC_OrderAgg); } if( w.pParse->nErr>0 ) return WRC_Abort; } pNC->ncFlags |= savedHasAgg; return WRC_Continue; Index: src/select.c ================================================================== --- src/select.c +++ src/select.c @@ -6381,10 +6381,43 @@ ** will be implemented as a co-routine and there is no advantage to ** flattening in that case. */ if( (pSub->selFlags & SF_Aggregate)!=0 ) continue; assert( pSub->pGroupBy==0 ); + + /* If a FROM-clause subquery has an ORDER BY clause that is not + ** really doing anything, then delete it now so that it does not + ** interfere with query flattening. See the discussion at + ** https://sqlite.org/forum/forumpost/2d76f2bcf65d256a + ** + ** Beware of these cases where the ORDER BY clause may not be safely + ** omitted: + ** + ** (1) There is also a LIMIT clause + ** (2) The subquery was added to help with window-function + ** processing + ** (3) The subquery is in the FROM clause of an UPDATE + ** (4) The outer query uses an aggregate function other than + ** the built-in count(), min(), or max(). + ** (5) The ORDER BY isn't going to accomplish anything because + ** one of: + ** (a) The outer query has a different ORDER BY clause + ** (b) The subquery is part of a join + ** See forum post 062d576715d277c8 + */ + if( pSub->pOrderBy!=0 + && (p->pOrderBy!=0 || pTabList->nSrc>1) /* Condition (5) */ + && pSub->pLimit==0 /* Condition (1) */ + && (pSub->selFlags & SF_OrderByReqd)==0 /* Condition (2) */ + && (p->selFlags & SF_OrderByReqd)==0 /* Condition (3) and (4) */ + && OptimizationEnabled(db, SQLITE_OmitOrderBy) + ){ + SELECTTRACE(0x100,pParse,p, + ("omit superfluous ORDER BY on %r FROM-clause subquery\n",i+1)); + sqlite3ExprListDelete(db, pSub->pOrderBy); + pSub->pOrderBy = 0; + } /* If the outer query contains a "complex" result set (that is, ** if the result set of the outer query uses functions or subqueries) ** and if the subquery contains an ORDER BY clause and if ** it will be implemented as a co-routine, then do not flatten. This Index: src/sqliteInt.h ================================================================== --- src/sqliteInt.h +++ src/sqliteInt.h @@ -1742,10 +1742,11 @@ #define SQLITE_SimplifyJoin 0x00002000 /* Convert LEFT JOIN to JOIN */ #define SQLITE_SkipScan 0x00004000 /* Skip-scans */ #define SQLITE_PropagateConst 0x00008000 /* The constant propagation opt */ #define SQLITE_MinMaxOpt 0x00010000 /* The min/max optimization */ #define SQLITE_SeekScan 0x00020000 /* The OP_SeekScan optimization */ +#define SQLITE_OmitOrderBy 0x00040000 /* Omit pointless ORDER BY */ #define SQLITE_AllOpts 0xffffffff /* All optimizations */ /* ** Macros for testing whether or not optimizations are enabled or disabled. */ @@ -1821,16 +1822,17 @@ ** values must correspond to OPFLAG_LENGTHARG and OPFLAG_TYPEOFARG. And ** SQLITE_FUNC_CONSTANT must be the same as SQLITE_DETERMINISTIC. There ** are assert() statements in the code to verify this. ** ** Value constraints (enforced via assert()): -** SQLITE_FUNC_MINMAX == NC_MinMaxAgg == SF_MinMaxAgg -** SQLITE_FUNC_LENGTH == OPFLAG_LENGTHARG -** SQLITE_FUNC_TYPEOF == OPFLAG_TYPEOFARG -** SQLITE_FUNC_CONSTANT == SQLITE_DETERMINISTIC from the API -** SQLITE_FUNC_DIRECT == SQLITE_DIRECTONLY from the API -** SQLITE_FUNC_UNSAFE == SQLITE_INNOCUOUS +** SQLITE_FUNC_MINMAX == NC_MinMaxAgg == SF_MinMaxAgg +** SQLITE_FUNC_ANYORDER == NC_OrderAgg == SF_OrderByReqd +** SQLITE_FUNC_LENGTH == OPFLAG_LENGTHARG +** SQLITE_FUNC_TYPEOF == OPFLAG_TYPEOFARG +** SQLITE_FUNC_CONSTANT == SQLITE_DETERMINISTIC from the API +** SQLITE_FUNC_DIRECT == SQLITE_DIRECTONLY from the API +** SQLITE_FUNC_UNSAFE == SQLITE_INNOCUOUS ** SQLITE_FUNC_ENCMASK depends on SQLITE_UTF* macros in the API */ #define SQLITE_FUNC_ENCMASK 0x0003 /* SQLITE_UTF8, SQLITE_UTF16BE or UTF16LE */ #define SQLITE_FUNC_LIKE 0x0004 /* Candidate for the LIKE optimization */ #define SQLITE_FUNC_CASE 0x0008 /* Case-sensitive LIKE-type function */ @@ -1851,10 +1853,11 @@ #define SQLITE_FUNC_INTERNAL 0x00040000 /* For use by NestedParse() only */ #define SQLITE_FUNC_DIRECT 0x00080000 /* Not for use in TRIGGERs or VIEWs */ #define SQLITE_FUNC_SUBTYPE 0x00100000 /* Result likely to have sub-type */ #define SQLITE_FUNC_UNSAFE 0x00200000 /* Function has side effects */ #define SQLITE_FUNC_INLINE 0x00400000 /* Functions implemented in-line */ +#define SQLITE_FUNC_ANYORDER 0x08000000 /* count/min/max aggregate */ /* Identifier numbers for each in-line function */ #define INLINEFUNC_coalesce 0 #define INLINEFUNC_implies_nonnull_row 1 #define INLINEFUNC_expr_implies_expr 2 @@ -3086,35 +3089,37 @@ /* ** Allowed values for the NameContext, ncFlags field. ** ** Value constraints (all checked via assert()): -** NC_HasAgg == SF_HasAgg == EP_Agg -** NC_MinMaxAgg == SF_MinMaxAgg == SQLITE_FUNC_MINMAX +** NC_HasAgg == SF_HasAgg == EP_Agg +** NC_MinMaxAgg == SF_MinMaxAgg == SQLITE_FUNC_MINMAX +** NC_OrderAgg == SF_OrderByReqd == SQLITE_FUNC_ANYORDER ** NC_HasWin == EP_Win ** */ -#define NC_AllowAgg 0x00001 /* Aggregate functions are allowed here */ -#define NC_PartIdx 0x00002 /* True if resolving a partial index WHERE */ -#define NC_IsCheck 0x00004 /* True if resolving a CHECK constraint */ -#define NC_GenCol 0x00008 /* True for a GENERATED ALWAYS AS clause */ -#define NC_HasAgg 0x00010 /* One or more aggregate functions seen */ -#define NC_IdxExpr 0x00020 /* True if resolving columns of CREATE INDEX */ -#define NC_SelfRef 0x0002e /* Combo: PartIdx, isCheck, GenCol, and IdxExpr */ -#define NC_VarSelect 0x00040 /* A correlated subquery has been seen */ -#define NC_UEList 0x00080 /* True if uNC.pEList is used */ -#define NC_UAggInfo 0x00100 /* True if uNC.pAggInfo is used */ -#define NC_UUpsert 0x00200 /* True if uNC.pUpsert is used */ -#define NC_UBaseReg 0x00400 /* True if uNC.iBaseReg is used */ -#define NC_MinMaxAgg 0x01000 /* min/max aggregates seen. See note above */ -#define NC_Complex 0x02000 /* True if a function or subquery seen */ -#define NC_AllowWin 0x04000 /* Window functions are allowed here */ -#define NC_HasWin 0x08000 /* One or more window functions seen */ -#define NC_IsDDL 0x10000 /* Resolving names in a CREATE statement */ -#define NC_InAggFunc 0x20000 /* True if analyzing arguments to an agg func */ -#define NC_FromDDL 0x40000 /* SQL text comes from sqlite_schema */ -#define NC_NoSelect 0x80000 /* Do not descend into sub-selects */ +#define NC_AllowAgg 0x000001 /* Aggregate functions are allowed here */ +#define NC_PartIdx 0x000002 /* True if resolving a partial index WHERE */ +#define NC_IsCheck 0x000004 /* True if resolving a CHECK constraint */ +#define NC_GenCol 0x000008 /* True for a GENERATED ALWAYS AS clause */ +#define NC_HasAgg 0x000010 /* One or more aggregate functions seen */ +#define NC_IdxExpr 0x000020 /* True if resolving columns of CREATE INDEX */ +#define NC_SelfRef 0x00002e /* Combo: PartIdx, isCheck, GenCol, and IdxExpr */ +#define NC_VarSelect 0x000040 /* A correlated subquery has been seen */ +#define NC_UEList 0x000080 /* True if uNC.pEList is used */ +#define NC_UAggInfo 0x000100 /* True if uNC.pAggInfo is used */ +#define NC_UUpsert 0x000200 /* True if uNC.pUpsert is used */ +#define NC_UBaseReg 0x000400 /* True if uNC.iBaseReg is used */ +#define NC_MinMaxAgg 0x001000 /* min/max aggregates seen. See note above */ +#define NC_Complex 0x002000 /* True if a function or subquery seen */ +#define NC_AllowWin 0x004000 /* Window functions are allowed here */ +#define NC_HasWin 0x008000 /* One or more window functions seen */ +#define NC_IsDDL 0x010000 /* Resolving names in a CREATE statement */ +#define NC_InAggFunc 0x020000 /* True if analyzing arguments to an agg func */ +#define NC_FromDDL 0x040000 /* SQL text comes from sqlite_schema */ +#define NC_NoSelect 0x080000 /* Do not descend into sub-selects */ +#define NC_OrderAgg 0x8000000 /* Has an aggregate other than count/min/max */ /* ** An instance of the following object describes a single ON CONFLICT ** clause in an upsert. ** @@ -3193,13 +3198,14 @@ /* ** Allowed values for Select.selFlags. The "SF" prefix stands for ** "Select Flag". ** ** Value constraints (all checked via assert()) -** SF_HasAgg == NC_HasAgg -** SF_MinMaxAgg == NC_MinMaxAgg == SQLITE_FUNC_MINMAX -** SF_FixedLimit == WHERE_USE_LIMIT +** SF_HasAgg == NC_HasAgg +** SF_MinMaxAgg == NC_MinMaxAgg == SQLITE_FUNC_MINMAX +** SF_OrderByReqd == NC_OrderAgg == SQLITE_FUNC_ANYORDER +** SF_FixedLimit == WHERE_USE_LIMIT */ #define SF_Distinct 0x0000001 /* Output should be DISTINCT */ #define SF_All 0x0000002 /* Includes the ALL keyword */ #define SF_Resolved 0x0000004 /* Identifiers have been resolved */ #define SF_Aggregate 0x0000008 /* Contains agg functions or a GROUP BY */ @@ -3224,10 +3230,11 @@ #define SF_NoopOrderBy 0x0400000 /* ORDER BY is ignored for this query */ #define SF_UFSrcCheck 0x0800000 /* Check pSrc as required by UPDATE...FROM */ #define SF_PushDown 0x1000000 /* SELECT has be modified by push-down opt */ #define SF_MultiPart 0x2000000 /* Has multiple incompatible PARTITIONs */ #define SF_CopyCte 0x4000000 /* SELECT statement is a copy of a CTE */ +#define SF_OrderByReqd 0x8000000 /* The ORDER BY clause may not be omitted */ /* ** The results of a SELECT can be distributed in several ways, as defined ** by one of the following macros. The "SRT" prefix means "SELECT Result ** Type". Index: src/update.c ================================================================== --- src/update.c +++ src/update.c @@ -259,10 +259,11 @@ } } pSelect = sqlite3SelectNew(pParse, pList, pSrc, pWhere2, pGrp, 0, pOrderBy2, SF_UFSrcCheck|SF_IncludeHidden, pLimit2 ); + if( pSelect ) pSelect->selFlags |= SF_OrderByReqd; sqlite3SelectDestInit(&dest, eDest, iEph); dest.iSDParm2 = (pPk ? pPk->nKeyCol : -1); sqlite3Select(pParse, pSelect, &dest); sqlite3SelectDelete(db, pSelect); } Index: src/window.c ================================================================== --- src/window.c +++ src/window.c @@ -1068,11 +1068,11 @@ p->pSrc = sqlite3SrcListAppend(pParse, 0, 0, 0); if( p->pSrc ){ Table *pTab2; p->pSrc->a[0].pSelect = pSub; sqlite3SrcListAssignCursors(pParse, p->pSrc); - pSub->selFlags |= SF_Expanded; + pSub->selFlags |= SF_Expanded|SF_OrderByReqd; pTab2 = sqlite3ResultSetOfSelect(pParse, pSub, SQLITE_AFF_NONE); pSub->selFlags |= (selFlags & SF_Aggregate); if( pTab2==0 ){ /* Might actually be some other kind of error, but in that case ** pParse->nErr will be set, so if SQLITE_NOMEM is set, we will get