SQLite

Check-in [ec7b648c7f]
Login

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

Overview
Comment:Support other frame types that use "<expr> PRECEDING" or "<expr> FOLLOWING" as start or end conditions.
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | exp-window-functions
Files: files | file ages | folders
SHA3-256: ec7b648c7f0ee266653561bbb9daa45b9be0d8a1a14f11dc93bce467c35154e6
User & Date: dan 2018-05-24 17:49:14.994
Context
2018-05-24
21:10
Allow "<expr> PRECEDING" to be used to specify the end of a window frame. (check-in: 7b709a989c user: dan tags: exp-window-functions)
17:49
Support other frame types that use "<expr> PRECEDING" or "<expr> FOLLOWING" as start or end conditions. (check-in: ec7b648c7f user: dan tags: exp-window-functions)
2018-05-23
20:55
Add support for "ROWS BETWEEN <expr> PRECEDING AND <expr> FOLLOWING" window frames. (check-in: 3a203660f1 user: dan tags: exp-window-functions)
Changes
Unified Diff Ignore Whitespace Patch
Changes to src/window.c.
89
90
91
92
93
94
95












































96
97
98
99
100
101
102
  sqlite3VdbeAddOp2(v, OP_Integer, 0, regZero);
  sqlite3VdbeAddOp2(v, OP_MustBeInt, reg, sqlite3VdbeCurrentAddr(v)+2);
  sqlite3VdbeAddOp3(v, OP_Ge, regZero, sqlite3VdbeCurrentAddr(v)+2, reg);
  sqlite3VdbeAddOp2(v, OP_Halt, SQLITE_ERROR, OE_Abort);
  sqlite3VdbeAppendP4(v, (void*)azErr[bEnd], P4_STATIC);
}













































static void windowCodeRowExprStep(
  Parse *pParse, 
  Select *p,
  WhereInfo *pWInfo,
  int regGosub, 
  int addrGosub
){







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







89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
  sqlite3VdbeAddOp2(v, OP_Integer, 0, regZero);
  sqlite3VdbeAddOp2(v, OP_MustBeInt, reg, sqlite3VdbeCurrentAddr(v)+2);
  sqlite3VdbeAddOp3(v, OP_Ge, regZero, sqlite3VdbeCurrentAddr(v)+2, reg);
  sqlite3VdbeAddOp2(v, OP_Halt, SQLITE_ERROR, OE_Abort);
  sqlite3VdbeAppendP4(v, (void*)azErr[bEnd], P4_STATIC);
}

/*
** ROWS BETWEEN <expr> PRECEDING    AND <expr> FOLLOWING
**
**   ...
**     if( new partition ){
**       Gosub flush_partition
**     }
**     Insert (record in eph-table)
**   sqlite3WhereEnd()
**   Gosub flush_partition
**
** flush_partition:
**   OpenDup (csr -> csr2)
**   OpenDup (csr -> csr3)
**   regPrec = <expr1>            // PRECEDING expression
**   regFollow = <expr2>          // FOLLOWING expression
**   if( regPrec<0 || regFollow<0 ) throw exception!
**   Rewind (csr,csr2,csr3)       // if EOF goto flush_partition_done
**     Aggstep (csr3)
**     Next(csr3)                 // if EOF fall-through
**     if( (regFollow--)<=0 ){
**       AggFinal (xValue)
**       Gosub addrGosub
**       Next(csr)                // if EOF goto flush_partition_done
**       if( (regPrec--)<=0 ){
**         AggStep (csr2, xInverse)
**         Next(csr2)
**       }
**     }
** flush_partition_done:
**   Close (csr2)
**   Close (csr3)
**   ResetSorter (csr)
**   Return
**
** ROWS BETWEEN <expr> PRECEDING    AND CURRENT ROW
** ROWS BETWEEN CURRENT ROW         AND <expr> FOLLOWING
** ROWS BETWEEN <expr> PRECEDING    AND UNBOUNDED FOLLOWING
** ROWS BETWEEN UNBOUNDED PRECEDING AND <expr> FOLLOWING
**
**   These are similar to the above. For "CURRENT ROW", intialize the
**   register to 0. For "UNBOUNDED ..." to infinity.
**
*/
static void windowCodeRowExprStep(
  Parse *pParse, 
  Select *p,
  WhereInfo *pWInfo,
  int regGosub, 
  int addrGosub
){
118
119
120
121
122
123
124









125
126
127
128
129
130
131
  int csrFollow = pParse->nTab++;
  int regPrec;                    /* Value of <expr> PRECEDING */
  int regFollow;                  /* Value of <expr> FOLLOWING */
  int addrNext;
  int addrGoto;
  int addrIfPos1;
  int addrIfPos2;










  pParse->nMem += nSub + 2;

  /* Allocate register and label for the "flush_partition" sub-routine. */
  regFlushPart = ++pParse->nMem;
  addrFlushPart = sqlite3VdbeMakeLabel(v);
  addrDone = sqlite3VdbeMakeLabel(v);







>
>
>
>
>
>
>
>
>







162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
  int csrFollow = pParse->nTab++;
  int regPrec;                    /* Value of <expr> PRECEDING */
  int regFollow;                  /* Value of <expr> FOLLOWING */
  int addrNext;
  int addrGoto;
  int addrIfPos1;
  int addrIfPos2;

  assert( pMWin->eStart==TK_PRECEDING 
       || pMWin->eStart==TK_CURRENT 
       || pMWin->eStart==TK_UNBOUNDED 
  );
  assert( pMWin->eEnd==TK_FOLLOWING 
       || pMWin->eEnd==TK_CURRENT 
       || pMWin->eEnd==TK_UNBOUNDED 
  );

  pParse->nMem += nSub + 2;

  /* Allocate register and label for the "flush_partition" sub-routine. */
  regFlushPart = ++pParse->nMem;
  addrFlushPart = sqlite3VdbeMakeLabel(v);
  addrDone = sqlite3VdbeMakeLabel(v);
169
170
171
172
173
174
175




176




177


178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193

  /* flush_partition: */
  sqlite3VdbeResolveLabel(v, addrFlushPart);
  sqlite3VdbeAddOp2(v, OP_Once, 0, sqlite3VdbeCurrentAddr(v)+3);
  sqlite3VdbeAddOp2(v, OP_OpenDup, csrPrec, pMWin->iEphCsr);
  sqlite3VdbeAddOp2(v, OP_OpenDup, csrFollow, pMWin->iEphCsr);





  sqlite3ExprCode(pParse, pMWin->pStart, regPrec);




  sqlite3ExprCode(pParse, pMWin->pEnd, regFollow);



  sqlite3VdbeAddOp2(v, OP_Null, 0, pMWin->regResult);
  sqlite3VdbeAddOp2(v, OP_Null, 0, pMWin->regAccum);

  /* If either regPrec or regFollow are not non-negative integers, throw an
  ** exception.  */
  windowCheckFrameValue(pParse, regPrec, 0);
  windowCheckFrameValue(pParse, regFollow, 1);

  sqlite3VdbeAddOp2(v, OP_Rewind, pMWin->iEphCsr, addrDone);
  sqlite3VdbeAddOp2(v, OP_Rewind, csrPrec, addrDone);
  sqlite3VdbeChangeP5(v, 1);
  sqlite3VdbeAddOp2(v, OP_Rewind, csrFollow, addrDone);
  sqlite3VdbeChangeP5(v, 1);

  /* Invoke AggStep function for each window function using the row that







>
>
>
>
|
>
>
>
>
|
>
>




<
<
<
<
<







222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244





245
246
247
248
249
250
251

  /* flush_partition: */
  sqlite3VdbeResolveLabel(v, addrFlushPart);
  sqlite3VdbeAddOp2(v, OP_Once, 0, sqlite3VdbeCurrentAddr(v)+3);
  sqlite3VdbeAddOp2(v, OP_OpenDup, csrPrec, pMWin->iEphCsr);
  sqlite3VdbeAddOp2(v, OP_OpenDup, csrFollow, pMWin->iEphCsr);

  /* If either regPrec or regFollow are not non-negative integers, throw 
  ** an exception.  */
  if( pMWin->pStart ){
    assert( pMWin->eStart==TK_PRECEDING );
    sqlite3ExprCode(pParse, pMWin->pStart, regPrec);
    windowCheckFrameValue(pParse, regPrec, 0);
  }
  if( pMWin->pEnd ){
    assert( pMWin->eEnd==TK_FOLLOWING );
    sqlite3ExprCode(pParse, pMWin->pEnd, regFollow);
    windowCheckFrameValue(pParse, regFollow, 1);
  }

  sqlite3VdbeAddOp2(v, OP_Null, 0, pMWin->regResult);
  sqlite3VdbeAddOp2(v, OP_Null, 0, pMWin->regAccum);






  sqlite3VdbeAddOp2(v, OP_Rewind, pMWin->iEphCsr, addrDone);
  sqlite3VdbeAddOp2(v, OP_Rewind, csrPrec, addrDone);
  sqlite3VdbeChangeP5(v, 1);
  sqlite3VdbeAddOp2(v, OP_Rewind, csrFollow, addrDone);
  sqlite3VdbeChangeP5(v, 1);

  /* Invoke AggStep function for each window function using the row that
201
202
203
204
205
206
207


208



209


210

211
212
213
214
215
216
217
218
219
220


221

222
223
224
225
226
227
228
229
230
231

232
233


234

235
236
237
238
239
240
241
    for(i=0; i<pWin->nArg; i++){
      sqlite3VdbeAddOp3(v, OP_Column, csrFollow, pWin->iArgCol+i, reg+i);
    }
    sqlite3VdbeAddOp3(v, OP_AggStep0, 0, reg, pWin->regAccum);
    sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
    sqlite3VdbeChangeP5(v, (u8)pWin->nArg);
  }


  sqlite3VdbeJumpHere(v, addrNext+1);






  addrIfPos1 = sqlite3VdbeAddOp3(v, OP_IfPos, regFollow, 0 , 1);

  for(pWin=pMWin; pWin; pWin=pWin->pNextWin){
    sqlite3VdbeAddOp3(v, 
        OP_AggFinal, pWin->regAccum, pWin->nArg, pWin->regResult
    );
    sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
  }
  sqlite3VdbeAddOp2(v, OP_Gosub, regGosub, addrGosub);
  sqlite3VdbeAddOp2(v, OP_Next, pMWin->iEphCsr, sqlite3VdbeCurrentAddr(v)+2);
  sqlite3VdbeAddOp2(v, OP_Goto, 0, addrDone);



  addrIfPos2 = sqlite3VdbeAddOp3(v, OP_IfPos, regPrec, 0 , 1);

  sqlite3VdbeAddOp2(v, OP_Next, csrPrec, sqlite3VdbeCurrentAddr(v)+1);
  for(pWin=pMWin; pWin; pWin=pWin->pNextWin){
    int i;
    for(i=0; i<pWin->nArg; i++){
      sqlite3VdbeAddOp3(v, OP_Column, csrPrec, pWin->iArgCol+i, reg+i);
    }
    sqlite3VdbeAddOp3(v, OP_AggStep0, 1, reg, pWin->regAccum);
    sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
    sqlite3VdbeChangeP5(v, (u8)pWin->nArg);
  }

  sqlite3VdbeJumpHere(v, addrIfPos2);



  sqlite3VdbeJumpHere(v, addrIfPos1);

  sqlite3VdbeAddOp2(v, OP_Goto, 0, addrNext);

  /* flush_partition_done: */
  sqlite3VdbeResolveLabel(v, addrDone);
  sqlite3VdbeAddOp1(v, OP_ResetSorter, pMWin->iEphCsr);
  sqlite3VdbeAddOp1(v, OP_Return, regFlushPart);








>
>
|
>
>
>
|
>
>
|
>










>
>
|
>
|
|
|
|
|
|
|
|
|
|
>
|
|
>
>
|
>







259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
    for(i=0; i<pWin->nArg; i++){
      sqlite3VdbeAddOp3(v, OP_Column, csrFollow, pWin->iArgCol+i, reg+i);
    }
    sqlite3VdbeAddOp3(v, OP_AggStep0, 0, reg, pWin->regAccum);
    sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
    sqlite3VdbeChangeP5(v, (u8)pWin->nArg);
  }
  if( pMWin->eEnd==TK_UNBOUNDED ){
    sqlite3VdbeAddOp2(v, OP_Goto, 0, addrNext);
    sqlite3VdbeJumpHere(v, addrNext+1);
    addrNext = sqlite3VdbeCurrentAddr(v);
  }else{
    sqlite3VdbeJumpHere(v, addrNext+1);
  }

  if( pMWin->eEnd==TK_FOLLOWING ){
    addrIfPos1 = sqlite3VdbeAddOp3(v, OP_IfPos, regFollow, 0 , 1);
  }
  for(pWin=pMWin; pWin; pWin=pWin->pNextWin){
    sqlite3VdbeAddOp3(v, 
        OP_AggFinal, pWin->regAccum, pWin->nArg, pWin->regResult
    );
    sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
  }
  sqlite3VdbeAddOp2(v, OP_Gosub, regGosub, addrGosub);
  sqlite3VdbeAddOp2(v, OP_Next, pMWin->iEphCsr, sqlite3VdbeCurrentAddr(v)+2);
  sqlite3VdbeAddOp2(v, OP_Goto, 0, addrDone);

  if( pMWin->eStart==TK_CURRENT || pMWin->eStart==TK_PRECEDING ){
    if( pMWin->eStart==TK_PRECEDING ){
      addrIfPos2 = sqlite3VdbeAddOp3(v, OP_IfPos, regPrec, 0 , 1);
    }
    sqlite3VdbeAddOp2(v, OP_Next, csrPrec, sqlite3VdbeCurrentAddr(v)+1);
    for(pWin=pMWin; pWin; pWin=pWin->pNextWin){
      int i;
      for(i=0; i<pWin->nArg; i++){
        sqlite3VdbeAddOp3(v, OP_Column, csrPrec, pWin->iArgCol+i, reg+i);
      }
      sqlite3VdbeAddOp3(v, OP_AggStep0, 1, reg, pWin->regAccum);
      sqlite3VdbeAppendP4(v, pWin->pFunc, P4_FUNCDEF);
      sqlite3VdbeChangeP5(v, (u8)pWin->nArg);
    }
    if( pMWin->eStart==TK_PRECEDING ){
      sqlite3VdbeJumpHere(v, addrIfPos2);
    }
  }
  if( pMWin->eEnd==TK_FOLLOWING ){
    sqlite3VdbeJumpHere(v, addrIfPos1);
  }
  sqlite3VdbeAddOp2(v, OP_Goto, 0, addrNext);

  /* flush_partition_done: */
  sqlite3VdbeResolveLabel(v, addrDone);
  sqlite3VdbeAddOp1(v, OP_ResetSorter, pMWin->iEphCsr);
  sqlite3VdbeAddOp1(v, OP_Return, regFlushPart);

424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
**
** ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
** ROWS BETWEEN CURRENT ROW AND CURRENT ROW
** ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
**
**========================================================================
**
** ROWS BETWEEN <expr> PRECEDING    AND <expr> FOLLOWING
**
**   ...
**     if( new partition ){
**       Gosub flush_partition
**     }
**     Insert (record in eph-table)
**   sqlite3WhereEnd()
**   Gosub flush_partition
**
** flush_partition:
**   OpenDup (csr -> csr2)
**   OpenDup (csr -> csr3)
**   regPrec = <expr1>            // PRECEDING expression
**   regFollow = <expr2>          // FOLLOWING expression
**   if( regPrec<0 || regFollow<0 ) throw exception!
**   Rewind (csr,csr2,csr3)       // if EOF goto flush_partition_done
**     Aggstep (csr3)
**     Next(csr3)                 // if EOF fall-through
**     if( (regFollow--)<=0 ){
**       AggFinal (xValue)
**       Gosub addrGosub
**       Next(csr)                // if EOF goto flush_partition_done
**       if( (regPrec--)<=0 ){
**         AggStep (csr2, xInverse)
**         Next(csr2)
**       }
**     }
** flush_partition_done:
**   Close (csr2)
**   Close (csr3)
**   ResetSorter (csr)
**   Return
**
** ROWS BETWEEN <expr> PRECEDING    AND CURRENT ROW
** ROWS BETWEEN CURRENT ROW         AND <expr> FOLLOWING
** ROWS BETWEEN <expr> PRECEDING    AND UNBOUNDED FOLLOWING
** ROWS BETWEEN UNBOUNDED PRECEDING AND <expr> FOLLOWING
**
**   These are similar to the above. For "CURRENT ROW", intialize the
**   register to 0. For "UNBOUNDED ..." to infinity.
**
** ROWS BETWEEN <expr> PRECEDING    AND <expr> PRECEDING
**
**   Replace the bit after "Rewind" in the above with:
**
**     if( (regFollow--)<=0 ){
**       AggStep (csr3)
**       Next (csr3)







<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<







497
498
499
500
501
502
503










































504
505
506
507
508
509
510
**
** ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
** ROWS BETWEEN CURRENT ROW AND CURRENT ROW
** ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
**
**========================================================================
**










































** ROWS BETWEEN <expr> PRECEDING    AND <expr> PRECEDING
**
**   Replace the bit after "Rewind" in the above with:
**
**     if( (regFollow--)<=0 ){
**       AggStep (csr3)
**       Next (csr3)
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
  int regGosub, 
  int addrGosub,
  int *pbLoop
){
  Window *pMWin = p->pWin;

  if( pMWin->eType==TK_ROWS 
   && pMWin->eStart==TK_PRECEDING
   && pMWin->eEnd==TK_FOLLOWING
  ){
    *pbLoop = 0;
    windowCodeRowExprStep(pParse, p, pWInfo, regGosub, addrGosub);
    return;
  }

  *pbLoop = 1;
  windowCodeDefaultStep(pParse, p, pWInfo, regGosub, addrGosub);
}









|
|











549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
  int regGosub, 
  int addrGosub,
  int *pbLoop
){
  Window *pMWin = p->pWin;

  if( pMWin->eType==TK_ROWS 
   && (pMWin->eStart==TK_PRECEDING || pMWin->eEnd==TK_FOLLOWING)
   && (pMWin->eStart!=TK_FOLLOWING || pMWin->eEnd==TK_PRECEDING)
  ){
    *pbLoop = 0;
    windowCodeRowExprStep(pParse, p, pWInfo, regGosub, addrGosub);
    return;
  }

  *pbLoop = 1;
  windowCodeDefaultStep(pParse, p, pWInfo, regGosub, addrGosub);
}


Changes to test/window2.tcl.
179
180
181
182
183
184
185






































186
187
188
189
190
191
192
execsql_test 2.7 {
  SELECT a, sum(d) OVER (
    PARTITION BY b
    ORDER BY d 
    ROWS BETWEEN 0 PRECEDING AND 0 FOLLOWING
  ) FROM t1
}







































puts $::fd finish_test
==========

execsql_test 3.1 {
  SELECT a, sum(d) OVER (
    PARTITION BY b ORDER BY d







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







179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
execsql_test 2.7 {
  SELECT a, sum(d) OVER (
    PARTITION BY b
    ORDER BY d 
    ROWS BETWEEN 0 PRECEDING AND 0 FOLLOWING
  ) FROM t1
}

execsql_test 2.8 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING
  ) FROM t1
}

execsql_test 2.9 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN UNBOUNDED PRECEDING AND 2 FOLLOWING
  ) FROM t1
}

execsql_test 2.10 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING
  ) FROM t1
}

execsql_test 2.11 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN 2 PRECEDING AND CURRENT ROW
  ) FROM t1
}

execsql_test 2.13 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN 2 PRECEDING AND UNBOUNDED FOLLOWING
  ) FROM t1
}


==========

puts $::fd finish_test
==========

execsql_test 3.1 {
  SELECT a, sum(d) OVER (
    PARTITION BY b ORDER BY d
Changes to test/window2.test.
91
92
93
94
95
96
97





































98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
  SELECT a, sum(d) OVER (
    PARTITION BY b
    ORDER BY d 
    ROWS BETWEEN 0 PRECEDING AND 0 FOLLOWING
  ) FROM t1
} {2 2   4 4   6 6   1 1   3 3   5 5}






































finish_test
#==========================================================================

do_execsql_test 2.1 {
  SELECT a, sum(d) OVER (
    PARTITION BY b ORDER BY d
    RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
  ) FROM t1
} {2 12   4 10   6 6   1 9   3 8   5 5}

do_execsql_test 2.2 {
  SELECT a, sum(d) OVER (
    ORDER BY b
    RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
  ) FROM t1
} {2 21   4 21   6 21   1 9   3 9   5 9}

do_execsql_test 2.3 {
  SELECT a, sum(d) OVER (
    ORDER BY d
    ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
  ) FROM t1
} {1 21   2 21   3 21   4 21   5 21   6 21}

do_execsql_test 2.4 {
  SELECT a, sum(d) OVER (
    ORDER BY d
    ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING
  ) FROM t1
} {1 3   2 6   3 9   4 12   5 15   6 11}

do_execsql_test 2.5 {
  SELECT a, sum(d) OVER (
    ORDER BY d
    ROWS BETWEEN 1 PRECEDING AND 1 PRECEDING
  ) FROM t1
} {1 {}   2 1   3 2   4 3   5 4   6 5}

finish_test







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



|






|






|






<
<
<
<
<
<
<
<
<
<
<
<
<
<

91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158














159
  SELECT a, sum(d) OVER (
    PARTITION BY b
    ORDER BY d 
    ROWS BETWEEN 0 PRECEDING AND 0 FOLLOWING
  ) FROM t1
} {2 2   4 4   6 6   1 1   3 3   5 5}

do_execsql_test 2.8 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING
  ) FROM t1
} {1 6   2 9   3 12   4 15   5 11   6 6}

do_execsql_test 2.9 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN UNBOUNDED PRECEDING AND 2 FOLLOWING
  ) FROM t1
} {1 6   2 10   3 15   4 21   5 21   6 21}

do_execsql_test 2.10 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING
  ) FROM t1
} {1 6   2 9   3 12   4 15   5 11   6 6}

do_execsql_test 2.11 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN 2 PRECEDING AND CURRENT ROW
  ) FROM t1
} {1 1   2 3   3 6   4 9   5 12   6 15}

do_execsql_test 2.13 {
  SELECT a, sum(d) OVER (
    ORDER BY d 
    ROWS BETWEEN 2 PRECEDING AND UNBOUNDED FOLLOWING
  ) FROM t1
} {1 21   2 21   3 21   4 20   5 18   6 15}

#==========================================================================

finish_test
#==========================================================================

do_execsql_test 3.1 {
  SELECT a, sum(d) OVER (
    PARTITION BY b ORDER BY d
    RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
  ) FROM t1
} {2 12   4 10   6 6   1 9   3 8   5 5}

do_execsql_test 3.2 {
  SELECT a, sum(d) OVER (
    ORDER BY b
    RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
  ) FROM t1
} {2 21   4 21   6 21   1 9   3 9   5 9}

do_execsql_test 3.3 {
  SELECT a, sum(d) OVER (
    ORDER BY d
    ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
  ) FROM t1
} {1 21   2 21   3 21   4 21   5 21   6 21}















finish_test