<tcl>hd_keywords {window functions}</tcl>
<title>SQLite SQL Window Function Support</title>
<table_of_contents>
<h2 style="margin-left:1.0em" notoc id=overview> Overview</h2>
<p>This page describes the support for SQL window functions added to SQLite
[version 3.25.0] ([dateof:3.25.0]). SQLite's window function support is closely
modeled on that of <a href=http://www.postgresql.org>PostgreSQL</a>.
<h1>Introduction to Window Functions</h1>
<p>A window function is a special type of SQL function for which the results
depend on the contents of a "window" of one or more contiguous rows returned
by the SELECT statement containing the window function. A window function may
only be used in the select-list or ORDER BY clause of a SELECT or sub-select
construction. The syntax for a window function is similar to that for a regular scalar SQL function except that it is followed by an OVER clause. The full
syntax is:
<codeblock>
<window-function> := <function>(<args...>) [<filter>] OVER (<window-definition>)
<filter> := FILTER (WHERE <expr>)
<window-definition> := [PARTITION BY <expression-list>] [ORDER BY <expression-list>] [<frame-specification>]
<frame-specification> := ROWS|RANGE BETWEEN <frame-boundary> AND <frame-boundary>
<frame-boundary> := UNBOUNDED PRECEDING
<frame-boundary> := <expr> PRECEDING
<frame-boundary> := CURRENT ROW
<frame-boundary> := <expr> FOLLOWING
<frame-boundary> := UNBOUNDED FOLLOWING
</codeblock>
<p>For example, given:
<codeblock>
CREATE TABLE t0(x INTEGER PRIMARY KEY, y TEXT);
INSERT INTO t0 VALUES (1, 'aaa'), (2, 'ccc'), (3, 'bbb');
</codeblock>
<p>Then:
<codeblock>
<i>-- The following SELECT statement returns:</i>
<i>-- </i>
<i>-- x | y | row_number</i>
-----------------------
<i>-- 1 | aaa | 1 </i>
<i>-- 2 | ccc | 3 </i>
<i>-- 3 | bbb | 2 </i>
<i>-- </i>
SELECT x, y, row_number() OVER (ORDER BY y) AS row_number FROM t0 ORDER BY x;
</codeblock>
<p>The example above uses the special built-in window function row_number().
This function returns a monotonically increasing integer assigned to each
row in order of the the "ORDER BY" clause within the
<i><window-definition></i> (in this case "ORDER BY y"). Note that
this does not affect the order in which results are returned to the user -
that is still governed by the ORDER BY clause attached to the SELECT
statement (in this case "ORDER BY x").
<p>Named <i><window-definitions></i> may also be added to a SELECT
statement using a WINDOW clause and then refered to by name within window
function invocations. For example, the following SELECT statement contains
two named <i><window-definitions></i>, "win1" and "win2":
<codeblock>
SELECT x, y, row_number() OVER <b>win1</b>, rank() OVER <b>win2</b> FROM t0
WINDOW <b>win1</b> AS (ORDER BY y RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW),
<b>win2</b> AS (PARTITION BY y ORDER BY x)
ORDER BY x;
</codeblock>
<p>The WINDOW clause, when one is present, comes after any HAVING clause and
before any ORDER BY.
<h1 tags="aggregate window functions">Aggregate Window Functions</h1>
<p> The examples in this section all assume that the database is populated as
follows:
<codeblock>
CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
INSERT INTO t1 VALUES (1, 'A', 'one' ),
(2, 'B', 'two' ),
(3, 'C', 'three'),
(4, 'D', 'one' ),
(5, 'E', 'two' ),
(6, 'F', 'three'),
(7, 'G', 'one' );
</codeblock>
<p> An aggregate window function is similar to an aggregate function, except
adding it to a query does not change the number of rows returned. Instead,
for each row the result of the aggregate window function is as if the
corresponding aggregate were run over all rows in the "window frame".
<codeblock>
<i>-- The following SELECT statement returns:</i>
<i>-- </i>
<i>-- a | b | group_concat</i>
-------------------------
<i>-- 1 | A | A.B </i>
<i>-- 2 | B | A.B.C </i>
<i>-- 3 | C | B.C.D </i>
<i>-- 4 | D | C.D.E </i>
<i>-- 5 | E | D.E.F </i>
<i>-- 6 | F | E.F.G </i>
<i>-- 7 | G | F.G </i>
<i>-- </i>
SELECT a, b, group_concat(b, '.') OVER (
ORDER BY a ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING
) AS group_concat FROM t1;
</codeblock>
<p> In the example above, the window frame consists of all rows between the
previous row ("1 PRECEDING") and the following row ("1 FOLLOWING"), inclusive,
where rows are sorted according to the ORDER BY clause in the
<i><window-definition></i> (in this case "ORDER BY a"). For example, the frame for the row with (a=3) consists of rows (2, 'B', 'two'), (3, 'C', 'three') and (4, 'D', 'one'). The result of group_concat(b, '.') for that row is therefore 'B.C.D'.
<p> The default <i><frame-specification></i> is:
<codeblock>
RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
</codeblock>
<p> This means that, after sorting the rows returned by the SELECT according to
the ORDER BY clause in the <window-definition>, the window frame consists
of all rows between the first row and the last row with the same values as the current row for all ORDER BY expressions. This implies that rows that have the same values for all ORDER BY expressions will also have the same value for the result of the window function (as the window frame is the same). For example:
<codeblock>
<i>-- The following SELECT statement returns:</i>
<i>-- </i>
<i>-- a | b | c | group_concat</i>
-----------------------------
<i>-- 1 | A | one | A.D.G </i>
<i>-- 2 | B | two | A.D.G.C.F.B.E</i>
<i>-- 3 | C | three | A.D.G.C.F </i>
<i>-- 4 | D | one | A.D.G </i>
<i>-- 5 | E | two | A.D.G.C.F.B.E</i>
<i>-- 6 | F | three | A.D.G.C.F </i>
<i>-- 7 | G | one | A.D.G </i>
<i>-- </i>
SELECT a, b, c,
group_concat(b, '.') OVER (ORDER BY c) AS group_concat
FROM t1 ORDER BY a;
</codeblock>
<p> All of SQLite's [Aggregate Functions|aggregate functions] may be used as aggregate window
functions. It is also possible to
[user-defined window functions|create user-defined aggregate window functions].
<h2>Frame Specifications</h2>
<p> A window frame specification consists of three things:
<ul>
<li> A frame type - either RANGE or ROWS.
<li> A starting frame boundary, and
<li> An ending frame boundary.
</ul>
<p> If the frame type is RANGE, then rows with the same values for all ORDER BY
expressions are considered "peers". Or, if there are no ORDER BY expressions,
all rows are peers. Rows that are peers always have the same window frames.
<p> There are five options for frame boundaries:
<table striped=1>
<tr><th>Frame Boundary <th>Description
<tr><td>UNBOUNDED PRECEDING <td> This may only be used as a starting frame
boundary. In which case the start of the frame is always the first
row in the set.
<tr><td><expr> PRECEDING <td> <expr>, which may not refer to any
table columns, must evaluate to a non-negative integer value. The start
or end of the frame is <expr> rows before the current row. "0
PRECEDING" is the same as "CURRENT ROW". This frame boundary type may
only be used with ROWS frames.
<tr><td>CURRENT ROW <td> The current row. For RANGE frame types, all peers of
the current row are also included in the window frame, regardless of
whether CURRENT ROW is used as the starting or ending frame boundary.
<tr><td><expr> FOLLOWING <td> <expr>, which may not refer to any
table columns, must evaluate to a non-negative integer value. The start
or end of the frame is <expr> rows after the current row. "0
FOLLOWING" is the same as "CURRENT ROW". This frame boundary type may
only be used with ROWS frames.
<tr><td>UNBOUNDED FOLLOWING <td> This may only be used as an ending
frame boundary. In which case the end of the frame is always the last
row in the set.
</table>
<p> The ending frame boundary must not take a form that appears higher in
the above list than the starting frame boundary.
<p> In the following example, the window frame for each row consists of all
rows from the current row to the end of the set, where rows are sorted
according to "ORDER BY a".
<codeblock>
<i>-- The following SELECT statement returns:</i>
<i>-- </i>
<i>-- c | a | b | group_concat</i>
---------------------------------
<i>-- one | 1 | A | A.D.G.C.F.B.E</i>
<i>-- one | 4 | D | D.G.C.F.B.E </i>
<i>-- one | 7 | G | G.C.F.B.E </i>
<i>-- three | 3 | C | C.F.B.E </i>
<i>-- three | 6 | F | F.B.E </i>
<i>-- two | 2 | B | B.E </i>
<i>-- two | 5 | E | E </i>
<i>-- </i>
SELECT c, a, b, group_concat(b, '.') OVER (
ORDER BY c, a ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
) AS group_concat
FROM t1 ORDER BY c, a;
</codeblock>
<h2>The PARTITION BY Clause</h2>
<p> A <i><window-definition></i> may also include a PARTITION BY clause.
If so, the rows returned by the SELECT statement are divided into groups -
partitions - with the same values for each PARTITION BY expression, and then
window-function processing performed as described above separately for each
partition. This is similar to the way the rows traversed by an aggregate query
are divided into groups before any aggregate processing is performed.
<p> For example:
<codeblock>
<i>-- The following SELECT statement returns:</i>
<i>-- </i>
<i>-- c | a | b | group_concat</i>
---------------------------------
<i>-- one | 1 | A | A.D.G </i>
<i>-- one | 4 | D | D.G </i>
<i>-- one | 7 | G | G </i>
<i>-- three | 3 | C | C.F </i>
<i>-- three | 6 | F | F </i>
<i>-- two | 2 | B | B.E </i>
<i>-- two | 5 | E | E </i>
<i>-- </i>
SELECT c, a, b, group_concat(b, '.') OVER (
PARTITION BY c ORDER BY a RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
) AS group_concat
FROM t1 ORDER BY c, a;
</codeblock>
<h2>The FILTER Clause</h2>
<p>If a FILTER clause is provided, then only rows for which the <i>expr</i> is
true are included in the window frame. The aggregate window still returns a
value for every row, but those for which the FILTER expression evaluates to
other than true are not included in the window frame for any row. For example:
<codeblock>
<i>-- The following SELECT statement returns:</i>
<i>-- </i>
<i>-- c | a | b | group_concat</i>
---------------------------------
<i>-- one | 1 | A | A </i>
<i>-- two | 2 | B | A </i>
<i>-- three | 3 | C | A.C </i>
<i>-- one | 4 | D | A.C.D </i>
<i>-- two | 5 | E | A.C.D </i>
<i>-- three | 6 | F | A.C.D.F </i>
<i>-- one | 7 | G | A.C.D.F.G </i>
<i>-- </i>
SELECT c, a, b, group_concat(b, '.') FILTER (WHERE c!='two') OVER (
ORDER BY a
) AS group_concat
FROM t1 ORDER BY a;
</codeblock>
<h1>Built-in Window Functions</h1>
<p> As well as aggregate window functions, SQLite features a set of built-in
window functions based on
<a href=https://www.postgresql.org/docs/10/static/functions-window.html>
those supported by PostgreSQL</a>.
<p> Built-in window functions honor any PARTITION BY clause in the same way
as aggregate window functions - each selected row is assigned to a partition
and each partition is processed separately. The ways in which any ORDER BY
clause affects each built-in window function is described below. Some of
the window functions (rank(), dense_rank(), percent_rank() and ntile()) use
the concept of "peer groups" (rows within the same partition that have the
same values for all ORDER BY expressions). In these cases, it does not matter
whether the <i><frame-specification></i> specifies ROWS or RANGE - for
the purposes of built-in window function processing, rows with the same values
for all ORDER BY expressions are considered peers regardless of the frame type.
<p> Most built-in window functions ignore the
<i><frame-specification></i>, the exceptions being first_value(),
last_value() and nth_value(). It is a syntax error to specify a FILTER
clause as part of a built-in window function invocation.
<p> SQLite supports the following 11 built-in window functions:
<dl>
<dt><p><b>row_number()</b>
<dd><p> The number of the row within the current partition. Rows are
numbered starting from 1 in the order defined by the ORDER BY clause in
the window definition, or in arbitrary order otherwise.
<dt><p><b>rank()</b>
<dd><p> The row_number() of the first peer in each group - the rank of the
current row with gaps. If there is no ORDER BY clause, then all rows
are considered peers and this function always returns 1.
<dt><p><b>dense_rank()</b>
<dd><p> The number of the current row's peer group within its partition - the
rank of the current row without gaps. Partitions are numbered starting
from 1 in the order defined by the ORDER BY clause in the window
definition. If there is no ORDER BY clause, then all rows are
considered peers and this function always returns 1.
<dt><p><b>percent_rank()</b>
<dd><p> Despite the name, this function always returns a value between 0.0
and 1.0 equal to (<i>rank</i> - 1)/(<i>partition-rows</i> - 1), where
<i>rank</i> is the value returned by built-in window function rank()
and <i>partition-rows</i> is the total number of rows in the
partition. If the partition contains only one row, this function
returns 0.0.
<dt><p><b>cume_dist()</b>
<dd><p> The cumulative distribution. Calculated as
<i>row-number</i>/<i>partition-rows</i>, where <i>row-number</i> is
the value returned by row_number() for the last peer in the group
and <i>partition-rows</i> the number of rows in the partition.
<dt><p><b>ntile(N)</b>
<dd><p> Argument <i>N</i> is handled as an integer. This function divides the
partition into N groups as evenly as possible and assigns an integer
between 1 and <i>N</i> to each group, in the order defined by the ORDER
BY clause, or in arbitrary order otherwise. If necessary, larger groups
occur first. This function returns the integer value assigned to the
group that the current row is a part of.
<dt><p><b>lag(expr)<br>lag(expr, offset)<br>lag(expr, offset, default)</b>
<dd><p> The first form of the lag() function returns the result of evaluating
expression <i>expr</i> against the previous row in the partition. Or, if
there is no previous row (because the current row is the first), NULL.
<p> If the <i>offset</i> argument is provided, then it must be a
non-negative integer. In this case the value returned is the result
of evaluating <i>expr</i> against the row <i>offset</i> rows before the
current row within the partition. If <i>offset</i> is 0, then
<i>expr</i> is evaluated against the current row. If there is no row
<i>offset</i> rows before the current row, NULL is returned.
<p> If <i>default</i> is also provided, then it is returned instead of
NULL if row identified by <i>offset</i> does not exist.
<dt><p><b>lead(expr)<br>lead(expr, offset)<br>lead(expr, offset, default)</b>
<dd><p> The first form of the lead() function returns the result of evaluating
expression <i>expr</i> against the next row in the partition. Or, if
there is no next row (because the current row is the last), NULL.
<p> If the <i>offset</i> argument is provided, then it must be a
non-negative integer. In this case the value returned is the result
of evaluating <i>expr</i> against the row <i>offset</i> rows after the
current row within the partition. If <i>offset</i> is 0, then
<i>expr</i> is evaluated against the current row. If there is no row
<i>offset</i> rows after the current row, NULL is returned.
<p> If <i>default</i> is also provided, then it is returned instead of
NULL if row identified by <i>offset</i> does not exist.
<dt><p><b>first_value(expr)</b>
<dd><p> This built-in window function calculates the window frame for each
row in the same way as an aggregate window function. It returns the
value of <i>expr</i> evaluated against the first row in the window frame
for each row.
<dt><p><b>last_value(expr)</b>
<dd><p> This built-in window function calculates the window frame for each
row in the same way as an aggregate window function. It returns the
value of <i>expr</i> evaluated against the last row in the window frame
for each row.
<dt><p><b>nth_value(expr, N)</b>
<dd><p> This built-in window function calculates the window frame for each
row in the same way as an aggregate window function. It returns the
value of <i>expr</i> evaluated against the row <i>N</i> of the window
frame. Rows are numbered within the window frame starting from 1 in
the order defined by the ORDER BY clause if one is present, or in
arbitrary order otherwise. If there is no <i>N</i>th row in the
partition, then NULL is returned.
<dd>
</dl>
<p>The examples in this section all assume the following data:
<codeblock>
CREATE TABLE t2(a, b);
INSERT INTO t2 VALUES('a', 'one'),
('a', 'two'),
('a', 'three'),
('b', 'four'),
('c', 'five'),
('c', 'six');
</codeblock>
<p>The following example illustrates the behaviour of the five ranking
functions - row_number(), rank(), dense_rank(), percent_rank() and
cume_dist().
<codeblock>
<i>-- The following SELECT statement returns:</i>
<i>-- </i>
<i>-- a | row_number | rank | dense_rank | percent_rank | cume_dist</i>
------------------------------------------------------------------
<i>-- a | 1 | 1 | 1 | 0.0 | 0.5</i>
<i>-- a | 2 | 1 | 1 | 0.0 | 0.5</i>
<i>-- a | 3 | 1 | 1 | 0.0 | 0.5</i>
<i>-- b | 4 | 4 | 2 | 0.6 | 0.66</i>
<i>-- c | 5 | 5 | 3 | 0.8 | 1.0</i>
<i>-- c | 6 | 5 | 3 | 0.8 | 1.0</i>
<i>-- </i>
SELECT a AS a,
row_number() OVER win AS row_number,
rank() OVER win AS rank,
dense_rank() OVER win AS dense_rank,
percent_rank() OVER win AS percent_rank,
cume_dist() OVER win AS cume_dist
FROM t2
WINDOW win AS (ORDER BY a);
</codeblock>
<p>The example below uses ntile() to divde the six rows into two groups (the
ntile(2) call) and into four groups (the ntile(4) call). For ntile(2), there
are three rows assigned to each group. For ntile(4), there are two groups of
two and two groups of one. The larger groups of two appear first.
<codeblock>
<i>-- The following SELECT statement returns:</i>
<i>-- </i>
<i>-- a | b | ntile_2 | ntile_4</i>
----------------------------------
<i>-- a | one | 1 | 1</i>
<i>-- a | two | 1 | 1</i>
<i>-- a | three | 1 | 2</i>
<i>-- b | four | 2 | 2</i>
<i>-- c | five | 2 | 3</i>
<i>-- c | six | 2 | 4</i>
<i>-- </i>
SELECT a AS a,
b AS b,
ntile(2) OVER win AS ntile_2,
ntile(4) OVER win AS ntile_4
FROM t2
WINDOW win AS (ORDER BY a);
</codeblock>
<p> The next example demonstrates lag(), lead(), first_value(), last_value()
and nth_value(). The <i><frame-specification></i> is ignored by both lag() and lead(), but respected by first_value(), last_value() and nth_value().
<codeblock>
<i>-- The following SELECT statement returns:</i>
<i>-- </i>
<i>-- b | lead | lag | first_value | last_value | nth_value_3</i>
-------------------------------------------------------------
<i>-- A | C | NULL | A | A | NULL </i>
<i>-- B | D | A | A | B | NULL </i>
<i>-- C | E | B | A | C | C </i>
<i>-- D | F | C | A | D | C </i>
<i>-- E | G | D | A | E | C </i>
<i>-- F | n/a | E | A | F | C </i>
<i>-- G | n/a | F | A | G | C </i>
<i>-- </i>
SELECT b AS b,
lead(b, 2, 'n/a') OVER win AS lead,
lag(b) OVER win AS lag,
first_value(b) OVER win AS first_value,
last_value(b) OVER win AS last_value,
nth_value(b, 3) OVER win AS nth_value_3
FROM t1
WINDOW win AS (ORDER BY b ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW)
</codeblock>
<h1 tags="user-defined window functions">User-Defined Aggregate Window Functions</h1>
<p> User-defined aggregate window functions may be created using the
[sqlite3_create_window_function]() API. Implementing an aggregate window
function is very similar to an ordinary aggregate function. Any user-defined
aggregate window function may also be used as an ordinary aggregate. To
implement a user-defined aggregate window function the application must
supply four callback functions:
<table striped=1>
<tr><th>Callback <th>Description
<tr><td>xStep <td>
This method is required by both window aggregate and legacy aggregate
function implementations. It is invoked to add a row to the current
window. The function arguments, if any, corresponding to the row being
added are passed to the implementation of xStep.
<tr><td>xFinal <td>
This method is required by both window aggregate and legacy aggregate
function implementations. It is invoked to return the current value
of the aggregate (determined by the contents of the current window),
and to free any resources allocated by earlier calls to xStep.
<tr><td>xValue <td>
This method is only required window aggregate functions, not legacy
aggregate function implementations. It is invoked to return the current
value of the aggregate. Unlike xFinal, the implementation should not
delete any context.
<tr><td>xInverse <td>
This method is only required window aggregate functions, not legacy
aggregate function implementations. It is invoked to remove a row
from the current window. The function arguments, if any, correspond
to the row being removed.
</table>
<p> The C code below implements a simple window aggregate function named
sumint(). This works in the same way as the built-in sum() function, except
that it throws an exception if passed an argument that is not an integer
value.
<codeblock>
<tcl>
proc C_Code {text} {
hd_puts "<pre>\n"
set iLine 0
foreach zLine [split [string trim $text "\n"] "\n"] {
regsub {^ } $zLine {} zLine
set zSubspec {<i>&</i>}
regsub {(/\*|\*\*|\*/).*} $zLine $zSubspec zLine
if {[regexp {(.*)(sqlite3[a-z0-9_]*)(.*)} $zLine -> one two three]} {
hd_puts $one
hd_resolve "\[$two\]"
hd_puts $three
} else {
hd_puts $zLine
}
hd_puts "\n"
}
hd_puts "</pre>\n"
}
C_Code {
/*
** xStep for sumint().
**
** Add the value of the argument to the aggregate context (an integer).
*/
static void sumintStep(
sqlite3_context *ctx,
int nArg,
sqlite3_value *apArg[]
){
sqlite3_int64 *pInt;
assert( nArg==1 );
if( sqlite3_value_type(apArg[0])!=SQLITE_INTEGER ){
sqlite3_result_error(ctx, "invalid argument", -1);
return;
}
pInt = (sqlite3_int64*)sqlite3_aggregate_context(ctx, sizeof(sqlite3_int64));
if( pInt ){
*pInt += sqlite3_value_int64(apArg[0]);
}
}
/*
** xInverse for sumint().
**
** This does the opposite of xStep() - subtracts the value of the argument
** from the current context value. The error checking can be omitted from
** this function, as it is only ever called after xStep() (so the aggregate
** context has already been allocated) and with a value that has already
** been passed to xStep() without error (so it must be an integer).
*/
static void sumintInverse(
sqlite3_context *ctx,
int nArg,
sqlite3_value *apArg[]
){
sqlite3_int64 *pInt;
assert( sqlite3_value_type(apArg[0])==SQLITE_INTEGER );
pInt = (sqlite3_int64*)sqlite3_aggregate_context(ctx, sizeof(sqlite3_int64));
*pInt -= sqlite3_value_int64(apArg[0]);
}
/*
** xFinal for sumint().
**
** Return the current value of the aggregate window function. Because
** this implementation does not allocate any resources beyond the buffer
** returned by sqlite3_aggregate_context, which is automatically freed
** by the system, there are no resources to free. And so this method is
** identical to xValue().
*/
static void sumintFinal(sqlite3_context *ctx){
sqlite3_int64 res = 0;
sqlite3_int64 *pInt;
pInt = (sqlite3_int64*)sqlite3_aggregate_context(ctx, 0);
if( pInt ) res = *pInt;
sqlite3_result_int64(ctx, res);
}
/*
** xValue for sumint().
**
** Return the current value of the aggregate window function. Because
*/
static void sumintValue(sqlite3_context *ctx){
sqlite3_int64 res = 0;
sqlite3_int64 *pInt;
pInt = (sqlite3_int64*)sqlite3_aggregate_context(ctx, 0);
if( pInt ) res = *pInt;
sqlite3_result_int64(ctx, res);
}
/*
** Register sumint() window aggregate with database handle db.
*/
int register_sumint(sqlite3 *db){
return sqlite3_create_window_function(db, "sumint", 1, SQLITE_UTF8, 0,
sumintStep, sumintFinal, sumintValue, sumintInverse, 0
);
}
}
</tcl>
</codeblock>
<p> The following example uses the sumint() function implemented by the above
C code. For each row, the window consists of the preceding row (if any), the current row and the following row (again, if any):
<codeblock>
CREATE TABLE t3(x, y);
INSERT INTO t3 VALUES('a', 4),
('b', 5),
('c', 3),
('d', 8),
('e', 1);
<i>-- Assuming the database is populated using the above script, the </i>
<i>-- following SELECT statement returns:</i>
<i>-- </i>
<i>-- x | sum_y</i>
--------------
<i>-- a | 9 </i>
<i>-- b | 12 </i>
<i>-- c | 16 </i>
<i>-- d | 12 </i>
<i>-- e | 9 </i>
<i>-- </i>
SELECT x, sumint(y) OVER (
ORDER BY x ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING
) AS sum_y
FROM t3 ORDER BY x;
</codeblock>
<p>In processing the query above, SQLite invokes the sumint callbacks as
follows:
<p>
<ol>
<li> <b>xStep(4)</b> - add "4" to the current window.
<li> <b>xStep(5)</b> - add "5" to the current window.
<li> <b>xValue()</b> - invoke xValue() to obtain the value of sumint() for
the row with (x='a'). The window currently consists of values 4 and 5,
and so the result is 9.
<li> <b>xStep(3)</b> - add "3" to the current window.
<li> <b>xValue()</b> - invoke xValue() to obtain the value of sumint() for
the row with (x='b'). The window currently consists of values 4, 5 and
3, and so the result is 12.
<li> <b>xInverse(4)</b> - remove "4" from the window.
<li> <b>xStep(8)</b> - add "8" to the current window. The window now consists
of values 5, 3 and 8.
<li> <b>xValue()</b> - invoked to obtain the value for the row with (x='c').
In this case, 16.
<li> <b>xInverse(5)</b> - remove value "5" from the window.
<li> <b>xStep(1)</b> - add value "1" to the window.
<li> <b>xValue()</b> - invoked to obtain the value for row (x='d').
<li> <b>xInverse(3)</b> - remove value "3" from the window. The window now
contains values 8 and 1 only.
<li> <b>xValue()</b> - invoked to obtain the value for row (x='d'). 9.
</ol>