From 26522d1c45763e482f6f51e25aa6c454527d3558 Mon Sep 17 00:00:00 2001 From: dan Date: Mon, 11 Jun 2018 18:16:51 +0000 Subject: [PATCH] Fix handling of window frames containing negative number of rows. e.g. "ROWS x PRECEDING AND y PRECEDING" where (xncFlags & NC_AllowAgg)==0) - || (pExpr->pWin && (pNC->ncFlags & NC_AllowWin)==0) + + if( is_agg==0 && pExpr->pWin ){ + sqlite3ErrorMsg(pParse, + "%.*s() may not be used as a window function", nId, zId + ); + pNC->nErr++; + }else if( + (is_agg && (pNC->ncFlags & NC_AllowAgg)==0) + || (is_agg && (pDef->funcFlags & SQLITE_FUNC_WINDOW) && !pExpr->pWin) + || (is_agg && pExpr->pWin && (pNC->ncFlags & NC_AllowWin)==0) ){ - const char *zType = pExpr->pWin ? "window" : "aggregate"; - sqlite3ErrorMsg(pParse, "misuse of %s function %.*s()",zType,nId,zId); + const char *zType; + if( (pDef->funcFlags & SQLITE_FUNC_WINDOW) || pExpr->pWin ){ + zType = "window"; + }else{ + zType = "aggregate"; + } + sqlite3ErrorMsg(pParse, "misuse of %s function %.*s()", zType, nId,zId); pNC->nErr++; is_agg = 0; }else if( no_such_func && pParse->db->init.busy==0 diff --git a/src/window.c b/src/window.c index fc4c7d905e..9c63362105 100644 --- a/src/window.c +++ b/src/window.c @@ -1,4 +1,5 @@ /* +** 2018 May 08 ** ** The author disclaims copyright to this source code. In place of ** a legal notice, here is a blessing: @@ -1258,13 +1259,26 @@ static void windowCodeRowExprStep( /* If this is "ROWS FOLLOWING AND ROWS FOLLOWING", do: ** + ** if( regEndpEnd && pMWin->pStart && pMWin->eStart==TK_FOLLOWING ){ assert( pMWin->eEnd==TK_FOLLOWING ); + sqlite3VdbeAddOp3(v, OP_Ge, regStart, sqlite3VdbeCurrentAddr(v)+2, regEnd); + sqlite3VdbeAddOp2(v, OP_Copy, regSize, regStart); sqlite3VdbeAddOp3(v, OP_Subtract, regStart, regEnd, regEnd); } + if( pMWin->pEnd && pMWin->pStart && pMWin->eEnd==TK_PRECEDING ){ + assert( pMWin->eStart==TK_PRECEDING ); + sqlite3VdbeAddOp3(v, OP_Le, regStart, sqlite3VdbeCurrentAddr(v)+3, regEnd); + sqlite3VdbeAddOp2(v, OP_Copy, regSize, regStart); + sqlite3VdbeAddOp2(v, OP_Copy, regSize, regEnd); + } + /* Initialize the accumulator register for each window function to NULL */ regArg = windowInitAccum(pParse, pMWin); @@ -1731,6 +1745,14 @@ void sqlite3WindowCodeStep( Window *pMWin = p->pWin; Window *pWin; + /* + ** Call windowCodeRowExprStep() for all window modes *except*: + ** + ** RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ** RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ** RANGE BETWEEN CURRENT ROW AND CURRENT ROW + ** ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + */ if( (pMWin->eType==TK_ROWS && (pMWin->eStart!=TK_UNBOUNDED||pMWin->eEnd!=TK_CURRENT||!pMWin->pOrderBy)) || (pMWin->eStart==TK_CURRENT&&pMWin->eEnd==TK_UNBOUNDED&&pMWin->pOrderBy) @@ -1739,6 +1761,11 @@ void sqlite3WindowCodeStep( return; } + /* + ** Call windowCodeCacheStep() if there is a window function that requires + ** that the entire partition be cached in a temp table before any rows + ** are returned. + */ for(pWin=pMWin; pWin; pWin=pWin->pNextWin){ FuncDef *pFunc = pWin->pFunc; if( (pFunc->funcFlags & SQLITE_FUNC_WINDOW_SIZE) diff --git a/test/window1.test b/test/window1.test index 81541dad4e..18d547963c 100644 --- a/test/window1.test +++ b/test/window1.test @@ -214,9 +214,43 @@ do_execsql_test 6.2 { a 1 1 a 2 2 a 3 3 a 4 4 a 5 5 a 6 6 a 7 7 } -do_catchsql_test 3.5 { +do_catchsql_test 6.3 { SELECT x, lag(x) FILTER (WHERE (x%2)=0) OVER w FROM t1 WINDOW w AS (ORDER BY x) } {1 {FILTER clause may only be used with aggregate window functions}} + +#------------------------------------------------------------------------- +# Attempt to use a window function as an aggregate. And other errors. +# +reset_db +do_execsql_test 7.0 { + CREATE TABLE t1(x, y); + INSERT INTO t1 VALUES(1, 2); + INSERT INTO t1 VALUES(3, 4); + INSERT INTO t1 VALUES(5, 6); + INSERT INTO t1 VALUES(7, 8); + INSERT INTO t1 VALUES(9, 10); +} + +do_catchsql_test 7.1.1 { + SELECT nth_value(x, 1) FROM t1; +} {1 {misuse of window function nth_value()}} +do_catchsql_test 7.1.2 { + SELECT * FROM t1 WHERE nth_value(x, 1) OVER (ORDER BY y); +} {1 {misuse of window function nth_value()}} +do_catchsql_test 7.1.3 { + SELECT count(*) FROM t1 GROUP BY y HAVING nth_value(x, 1) OVER (ORDER BY y); +} {1 {misuse of window function nth_value()}} +do_catchsql_test 7.1.4 { + SELECT count(*) FROM t1 GROUP BY nth_value(x, 1) OVER (ORDER BY y); +} {1 {misuse of window function nth_value()}} +do_catchsql_test 7.1.5 { + SELECT count(*) FROM t1 LIMIT nth_value(x, 1) OVER (ORDER BY y); +} {1 {no such column: x}} +do_catchsql_test 7.1.6 { + SELECT trim(x) OVER (ORDER BY y) FROM t1; +} {1 {trim() may not be used as a window function}} + finish_test + diff --git a/test/window4.tcl b/test/window4.tcl index 30b56ca4e8..6a85a2a290 100644 --- a/test/window4.tcl +++ b/test/window4.tcl @@ -102,6 +102,32 @@ execsql_test 3.4 { WINDOW w AS (ORDER BY a) } +execsql_test 3.5.1 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 1 PRECEDING AND 2 PRECEDING) + FROM t5 +} +execsql_test 3.5.2 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 1 PRECEDING AND 1 PRECEDING) + FROM t5 +} +execsql_test 3.5.3 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 0 PRECEDING AND 0 PRECEDING) + FROM t5 +} + +execsql_test 3.6.1 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 2 FOLLOWING AND 1 FOLLOWING) + FROM t5 +} +execsql_test 3.6.2 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 1 FOLLOWING AND 1 FOLLOWING) + FROM t5 +} +execsql_test 3.6.3 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 0 FOLLOWING AND 0 FOLLOWING) + FROM t5 +} + finish_test diff --git a/test/window4.test b/test/window4.test index 70963800f5..317824e4c4 100644 --- a/test/window4.test +++ b/test/window4.test @@ -176,14 +176,39 @@ do_execsql_test 3.3 { ORDER BY a; } {1 1 5 2 2 4 3 3 3 4 4 2 5 5 1} -explain_i { - SELECT a, max(a) FILTER (WHERE (a%2)=0) OVER w FROM t5 - WINDOW w AS (ORDER BY a) - } - breakpoint do_execsql_test 3.4 { SELECT a, max(a) FILTER (WHERE (a%2)=0) OVER w FROM t5 WINDOW w AS (ORDER BY a) } {1 {} 2 2 3 2 4 4 5 4} +do_execsql_test 3.5.1 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 1 PRECEDING AND 2 PRECEDING) + FROM t5 +} {1 {} 2 {} 3 {} 4 {} 5 {}} + +do_execsql_test 3.5.2 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 1 PRECEDING AND 1 PRECEDING) + FROM t5 +} {1 {} 2 one 3 two 4 three 5 four} + +do_execsql_test 3.5.3 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 0 PRECEDING AND 0 PRECEDING) + FROM t5 +} {1 one 2 two 3 three 4 four 5 five} + +do_execsql_test 3.6.1 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 2 FOLLOWING AND 1 FOLLOWING) + FROM t5 +} {1 {} 2 {} 3 {} 4 {} 5 {}} + +do_execsql_test 3.6.2 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 1 FOLLOWING AND 1 FOLLOWING) + FROM t5 +} {1 two 2 three 3 four 4 five 5 {}} + +do_execsql_test 3.6.3 { + SELECT a, max(c) OVER (ORDER BY a ROWS BETWEEN 0 FOLLOWING AND 0 FOLLOWING) + FROM t5 +} {1 one 2 two 3 three 4 four 5 five} + finish_test