/ Check-in [ceaf798e]
Login

Many hyperlinks are disabled.
Use anonymous login to enable hyperlinks.

Overview
Comment:Add support for FILTER clause on aggregate window functions.
Downloads: Tarball | ZIP archive | SQL archive
Timelines: family | ancestors | descendants | both | exp-window-functions
Files: files | file ages | folders
SHA3-256: ceaf798ea09184bc0e7d3dcf3ad4d909d2e4e7018754a8417a813f33010140a7
User & Date: dan 2018-06-09 17:43:45
Context
2018-06-09
17:58
Update the amalgamation build script to include window.c. check-in: 21d2f4a6 user: dan tags: exp-window-functions
17:43
Add support for FILTER clause on aggregate window functions. check-in: ceaf798e user: dan tags: exp-window-functions
2018-06-08
20:58
Add support for the WINDOW clause. check-in: 19c983b5 user: dan tags: exp-window-functions
Changes
Hide Diffs Unified Diffs Show Whitespace Changes Patch

Changes to src/window.c.

407
408
409
410
411
412
413





414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
...
598
599
600
601
602
603
604




605
606
607
608
609
610
611
...
815
816
817
818
819
820
821














822
823
824
825
826
827
828
829

830
831
832
833
834
835
836
...
851
852
853
854
855
856
857

858
859
860
861
862
863
864
    pWin->pStart = sqlite3ExprDup(pParse->db, p->pStart, 0);
    pWin->pEnd = sqlite3ExprDup(pParse->db, p->pEnd, 0);
    pWin->eStart = p->eStart;
    pWin->eEnd = p->eEnd;
  }
  if( pFunc->funcFlags & SQLITE_FUNC_WINDOW ){
    sqlite3 *db = pParse->db;





    if( pFunc->xSFunc==row_numberStepFunc || pFunc->xSFunc==ntileStepFunc ){
      sqlite3ExprDelete(db, pWin->pStart);
      sqlite3ExprDelete(db, pWin->pEnd);
      pWin->pStart = pWin->pEnd = 0;
      pWin->eType = TK_ROWS;
      pWin->eStart = TK_UNBOUNDED;
      pWin->eEnd = TK_CURRENT;
    }

    if( pFunc->xSFunc==dense_rankStepFunc || pFunc->xSFunc==rankStepFunc
     || pFunc->xSFunc==percent_rankStepFunc || pFunc->xSFunc==cume_distStepFunc
    ){
      sqlite3ExprDelete(db, pWin->pStart);
      sqlite3ExprDelete(db, pWin->pEnd);
      pWin->pStart = pWin->pEnd = 0;
................................................................................
    /* Append the arguments passed to each window function to the
    ** sub-select expression list. Also allocate two registers for each
    ** window function - one for the accumulator, another for interim
    ** results.  */
    for(pWin=pMWin; pWin; pWin=pWin->pNextWin){
      pWin->iArgCol = (pSublist ? pSublist->nExpr : 0);
      pSublist = exprListAppendList(pParse, pSublist, pWin->pOwner->x.pList);




      pWin->regAccum = ++pParse->nMem;
      pWin->regResult = ++pParse->nMem;
      sqlite3VdbeAddOp2(v, OP_Null, 0, pWin->regAccum);
    }

    pSub = sqlite3SelectNew(
        pParse, pSublist, pSrc, pWhere, pGroupBy, pHaving, pSort, 0, 0
................................................................................
      assert( bInverse==0 || bInverse==1 );
      sqlite3VdbeAddOp2(v, OP_AddImm, pWin->regApp+1-bInverse, 1);
    }else if( pWin->pFunc->xSFunc==leadStepFunc 
           || pWin->pFunc->xSFunc==lagStepFunc 
    ){
      /* no-op */
    }else{














      if( pWin->pFunc->funcFlags & SQLITE_FUNC_NEEDCOLL ){
        CollSeq *pColl;
        pColl = sqlite3ExprCollSeq(pParse, pWin->pOwner->x.pList->a[0].pExpr);
        sqlite3VdbeAddOp4(v, OP_CollSeq, 0,0,0, (const char*)pColl, P4_COLLSEQ);
      }
      sqlite3VdbeAddOp3(v, OP_AggStep0, bInverse, regArg, pWin->regAccum);
      sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
      sqlite3VdbeChangeP5(v, (u8)nArg);

    }
  }
}

static void windowAggFinal(Parse *pParse, Window *pMWin, int bFinal){
  Vdbe *v = sqlite3GetVdbe(pParse);
  Window *pWin;
................................................................................
      if( bFinal==0 ){
        sqlite3VdbeAddOp2(v, OP_Null, 0, pWin->regResult);
      }
      sqlite3VdbeAddOp2(v, OP_AggFinal, pWin->regAccum, pWin->nArg);
      sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
      if( bFinal ){
        sqlite3VdbeAddOp2(v, OP_Copy, pWin->regAccum, pWin->regResult);

      }else{
        sqlite3VdbeChangeP3(v, -1, pWin->regResult);
      }
    }
  }
}








>
>
>
>
>







|







 







>
>
>
>







 







>
>
>
>
>
>
>
>
>
>
>
>
>
>


|





>







 







>







407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
...
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
...
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
...
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
    pWin->pStart = sqlite3ExprDup(pParse->db, p->pStart, 0);
    pWin->pEnd = sqlite3ExprDup(pParse->db, p->pEnd, 0);
    pWin->eStart = p->eStart;
    pWin->eEnd = p->eEnd;
  }
  if( pFunc->funcFlags & SQLITE_FUNC_WINDOW ){
    sqlite3 *db = pParse->db;
    if( pWin->pFilter ){
      sqlite3ErrorMsg(pParse, 
          "FILTER clause may only be used with aggregate window functions"
      );
    }else
    if( pFunc->xSFunc==row_numberStepFunc || pFunc->xSFunc==ntileStepFunc ){
      sqlite3ExprDelete(db, pWin->pStart);
      sqlite3ExprDelete(db, pWin->pEnd);
      pWin->pStart = pWin->pEnd = 0;
      pWin->eType = TK_ROWS;
      pWin->eStart = TK_UNBOUNDED;
      pWin->eEnd = TK_CURRENT;
    }else

    if( pFunc->xSFunc==dense_rankStepFunc || pFunc->xSFunc==rankStepFunc
     || pFunc->xSFunc==percent_rankStepFunc || pFunc->xSFunc==cume_distStepFunc
    ){
      sqlite3ExprDelete(db, pWin->pStart);
      sqlite3ExprDelete(db, pWin->pEnd);
      pWin->pStart = pWin->pEnd = 0;
................................................................................
    /* Append the arguments passed to each window function to the
    ** sub-select expression list. Also allocate two registers for each
    ** window function - one for the accumulator, another for interim
    ** results.  */
    for(pWin=pMWin; pWin; pWin=pWin->pNextWin){
      pWin->iArgCol = (pSublist ? pSublist->nExpr : 0);
      pSublist = exprListAppendList(pParse, pSublist, pWin->pOwner->x.pList);
      if( pWin->pFilter ){
        Expr *pFilter = sqlite3ExprDup(db, pWin->pFilter, 0);
        pSublist = sqlite3ExprListAppend(pParse, pSublist, pFilter);
      }
      pWin->regAccum = ++pParse->nMem;
      pWin->regResult = ++pParse->nMem;
      sqlite3VdbeAddOp2(v, OP_Null, 0, pWin->regAccum);
    }

    pSub = sqlite3SelectNew(
        pParse, pSublist, pSrc, pWhere, pGroupBy, pHaving, pSort, 0, 0
................................................................................
      assert( bInverse==0 || bInverse==1 );
      sqlite3VdbeAddOp2(v, OP_AddImm, pWin->regApp+1-bInverse, 1);
    }else if( pWin->pFunc->xSFunc==leadStepFunc 
           || pWin->pFunc->xSFunc==lagStepFunc 
    ){
      /* no-op */
    }else{
      int addrIf = 0;
      if( pWin->pFilter ){
        int regTmp;
        if( csr>0 ){
          regTmp = sqlite3GetTempReg(pParse);
          sqlite3VdbeAddOp3(v, OP_Column, csr, pWin->iArgCol+pWin->nArg,regTmp);
        }else{
          regTmp = regArg + pWin->nArg;
        }
        addrIf = sqlite3VdbeAddOp3(v, OP_IfNot, regTmp, 0, 1);
        if( csr>0 ){
          sqlite3ReleaseTempReg(pParse, regTmp);
        }
      }
      if( pWin->pFunc->funcFlags & SQLITE_FUNC_NEEDCOLL ){
        CollSeq *pColl;
        pColl = sqlite3ExprNNCollSeq(pParse, pWin->pOwner->x.pList->a[0].pExpr);
        sqlite3VdbeAddOp4(v, OP_CollSeq, 0,0,0, (const char*)pColl, P4_COLLSEQ);
      }
      sqlite3VdbeAddOp3(v, OP_AggStep0, bInverse, regArg, pWin->regAccum);
      sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
      sqlite3VdbeChangeP5(v, (u8)nArg);
      if( addrIf ) sqlite3VdbeJumpHere(v, addrIf);
    }
  }
}

static void windowAggFinal(Parse *pParse, Window *pMWin, int bFinal){
  Vdbe *v = sqlite3GetVdbe(pParse);
  Window *pWin;
................................................................................
      if( bFinal==0 ){
        sqlite3VdbeAddOp2(v, OP_Null, 0, pWin->regResult);
      }
      sqlite3VdbeAddOp2(v, OP_AggFinal, pWin->regAccum, pWin->nArg);
      sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
      if( bFinal ){
        sqlite3VdbeAddOp2(v, OP_Copy, pWin->regAccum, pWin->regResult);
        sqlite3VdbeAddOp2(v, OP_Null, 0, pWin->regAccum);
      }else{
        sqlite3VdbeChangeP3(v, -1, pWin->regResult);
      }
    }
  }
}

Changes to test/window1.test.

210
211
212
213
214
215
216




217
218
do_execsql_test 6.2 {
  SELECT * FROM t2, (SELECT x, count(*) OVER (ORDER BY x) FROM t1);
} {
  b 1 1 b 2 2 b 3 3 b 4 4 b 5 5 b 6 6 b 7 7
  a 1 1 a 2 2 a 3 3 a 4 4 a 5 5 a 6 6 a 7 7
}






finish_test







>
>
>
>


210
211
212
213
214
215
216
217
218
219
220
221
222
do_execsql_test 6.2 {
  SELECT * FROM t2, (SELECT x, count(*) OVER (ORDER BY x) FROM t1);
} {
  b 1 1 b 2 2 b 3 3 b 4 4 b 5 5 b 6 6 b 7 7
  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 {
  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}}

finish_test

Changes to test/window3.tcl.

280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
...
296
297
298
299
300
301
302




















303
304
305
306
  execsql_test 1.$tn.13.6 "
    SELECT lag(b,b) OVER (PARTITION BY b%2,a ORDER BY b%10 $window) FROM t2
  "

  execsql_test 1.$tn.14.1 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER (ORDER BY a $window) FROM t2
  "

  execsql_test 1.$tn.14.2 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER (PARTITION BY b%10 ORDER BY a $window) FROM t2
  "
  execsql_test 1.$tn.14.3 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER ( ORDER BY b,a $window ) FROM t2
  "
  execsql_test 1.$tn.14.4 "
................................................................................
  "
  execsql_test 1.$tn.14.5 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER ( ORDER BY b%10,a $window ) FROM t2
  "
  execsql_test 1.$tn.14.6 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER (PARTITION BY b%2,a ORDER BY b%10 $window) FROM t2
  "




















}

finish_test








<







 







>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>




280
281
282
283
284
285
286

287
288
289
290
291
292
293
...
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
  execsql_test 1.$tn.13.6 "
    SELECT lag(b,b) OVER (PARTITION BY b%2,a ORDER BY b%10 $window) FROM t2
  "

  execsql_test 1.$tn.14.1 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER (ORDER BY a $window) FROM t2
  "

  execsql_test 1.$tn.14.2 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER (PARTITION BY b%10 ORDER BY a $window) FROM t2
  "
  execsql_test 1.$tn.14.3 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER ( ORDER BY b,a $window ) FROM t2
  "
  execsql_test 1.$tn.14.4 "
................................................................................
  "
  execsql_test 1.$tn.14.5 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER ( ORDER BY b%10,a $window ) FROM t2
  "
  execsql_test 1.$tn.14.6 "
    SELECT string_agg(CAST(b AS TEXT), '.') OVER (PARTITION BY b%2,a ORDER BY b%10 $window) FROM t2
  "

  execsql_test 1.$tn.15.1 "
    SELECT string_agg(CAST(b AS TEXT), '.') 
    FILTER (WHERE a%2=0) OVER (ORDER BY a $window) FROM t2
  "

  execsql_test 1.$tn.15.2 "
    SELECT string_agg(CAST(b AS TEXT), '.') 
    FILTER (WHERE 0=1) OVER (ORDER BY a $window) FROM t2
  "

  execsql_test 1.$tn.15.3 "
    SELECT string_agg(CAST(b AS TEXT), '.') 
    FILTER (WHERE 1=0) OVER (PARTITION BY (a%10) ORDER BY a $window) FROM t2
  "

  execsql_test 1.$tn.15.4 "
    SELECT string_agg(CAST(b AS TEXT), '.') 
    FILTER (WHERE a%2=0) OVER (PARTITION BY (a%10) ORDER BY a $window) FROM t2
  "
}

finish_test

Changes to test/window3.test.

cannot compute difference between binary files

Changes to test/window4.tcl.

92
93
94
95
96
97
98






99
100
101

execsql_test 3.3 {
  SELECT a, count(*) OVER abc, count(*) OVER def FROM t5
  WINDOW abc AS (ORDER BY a), 
         def AS (ORDER BY a DESC)
  ORDER BY a;
}







finish_test








>
>
>
>
>
>



92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107

execsql_test 3.3 {
  SELECT a, count(*) OVER abc, count(*) OVER def FROM t5
  WINDOW abc AS (ORDER BY a), 
         def AS (ORDER BY a DESC)
  ORDER BY a;
}

execsql_test 3.4 {
  SELECT a, max(a) FILTER (WHERE (a%2)=0) OVER w FROM t5 
  WINDOW w AS (ORDER BY a)
}


finish_test

Changes to test/window4.test.

172
173
174
175
176
177
178










179
do_execsql_test 3.3 {
  SELECT a, count(*) OVER abc, count(*) OVER def FROM t5
  WINDOW abc AS (ORDER BY a), 
         def AS (ORDER BY a DESC)
  ORDER BY a;
} {1 1 5   2 2 4   3 3 3   4 4 2   5 5 1}











finish_test







>
>
>
>
>
>
>
>
>
>

172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
do_execsql_test 3.3 {
  SELECT a, count(*) OVER abc, count(*) OVER def FROM t5
  WINDOW abc AS (ORDER BY a), 
         def AS (ORDER BY a DESC)
  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}

finish_test