Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Work on the window function documentation. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA3-256: |
4b4ef30fa63b0f56641732407ae93ac2 |
User & Date: | drh 2019-03-28 00:46:56.107 |
Context
2019-03-28
| ||
01:20 | Minor tweak to the window function documentation. (check-in: 7113d8b989 user: drh tags: trunk) | |
00:46 | Work on the window function documentation. (check-in: 4b4ef30fa6 user: drh tags: trunk) | |
2019-03-27
| ||
19:02 | Fix problems in windowfunctions.in. (check-in: dac96e63bd user: dan tags: trunk) | |
Changes
Changes to pages/changes.in.
︙ | ︙ | |||
22 23 24 25 26 27 28 | } chng {2019-04-00 (3.28.0)} { <li> Enhanced [window functions]: <ol type="a"> <li> Add support the [EXCLUDE clause]. <li> Add support for [window chaining]. | | | > | | 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 | } chng {2019-04-00 (3.28.0)} { <li> Enhanced [window functions]: <ol type="a"> <li> Add support the [EXCLUDE clause]. <li> Add support for [window chaining]. <li> Add support for [GROUPS frames]. <li> Add support for "[RANGE n PRECEDING|<expr> PRECEDING]" and "[RANGE n FOLLOWING|<expr> FOLLOWING]" boundaries in RANGE [frames]. </ol> <li> Added the new [sqlite3_stmt_isexplain(S)] interface for determining whether or not a [prepared statement] is an [EXPLAIN]. <li> Enhanced [VACUUM INTO] so that it works for read-only databases. <li> New query optimizations: <ol type="a"> <li> Enable the [LIKE optimization] for cases when the ESCAPE keyword |
︙ | ︙ |
Changes to pages/windowfunctions.in.
1 2 3 4 5 6 7 | <tcl>hd_keywords {window functions} {window function}</tcl> <title>Window Functions</title> <table_of_contents> <h1>Introduction to Window Functions</h1> | | > > > > > > > > < < < < < > > > > > > > > | > | < < < < | | | 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 | <tcl>hd_keywords {window functions} {window function}</tcl> <title>Window Functions</title> <table_of_contents> <h1>Introduction to Window Functions</h1> <p>A window function is an SQL function where the input values are taken from a "window" of one or more rows in the results set of a SELECT statement. <p>Window functions are distinguished from other SQL functions by the presence of an OVER clause. If a function has an OVER clause, then it is a window function. If it lacks an OVER clause, then it is an ordinary aggregate or scalar function. Window functions might also have a FILTER clause in between the function and the OVER clause. <p>The syntax for a window function is like this: <tcl> RecursiveBubbleDiagram window-function-invocation window-defn frame-spec filter </tcl> <p>Unlike ordinary functions, window functions cannot use the DISTINCT keyword. Also, Window functions may only appear in the result set and in the ORDER BY clause of a SELECT statement. <p>Window functions come in two varieties: [aggregate window functions] and [built-in window functions]. Any [aggfunc|aggregate function], including application-defined aggregate functions, can often be used as an aggregate window function, simply by adding an appropriate OVER clause. The built-in window functions, however, special-case handling in the query planner and hence cannot be extended by the application. <p>Here is an example using the built-in row_number() window function: <codeblock> CREATE TABLE t0(x INTEGER PRIMARY KEY, y TEXT); INSERT INTO t0 VALUES (1, 'aaa'), (2, 'ccc'), (3, 'bbb'); <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 row_number() window function assigns consecutive integers to each row in order of the "ORDER BY" clause within the <yynonterm>window-defn</yynonterm> (in this case "ORDER BY y"). Note that this does not affect the order in which results are returned from the overall query. The order of the final output is still governed by the ORDER BY clause attached to the SELECT statement (in this case "ORDER BY x"). |
︙ | ︙ | |||
69 70 71 72 73 74 75 | <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. | > | | > | > | 77 78 79 80 81 82 83 84 85 86 87 88 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 | <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. <tcl>hd_fragment aggwinfunc {aggregate window functions}</tcl> <h1>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 [aggfunc|ordinary 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" specified by the OVER clause. <codeblock> <i>-- The following SELECT statement returns:</i> <i>-- </i> <i>-- a | b | group_concat</i> ------------------------- |
︙ | ︙ | |||
120 121 122 123 124 125 126 127 | 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> 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]. | | > > | > > > > > > > | > > > > > > > > > > > > > > > > > > | > > > > | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | > > > > > > > | > > | | < | 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 160 161 162 163 164 165 166 167 168 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 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 231 232 233 234 235 236 237 238 | 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> 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]. <tcl>hd_fragment ptxn {partition}</tcl> <h2>The PARTITION BY Clause</h2> <p> For the purpose of computing window functions, the entire result set of a query is divided into one or more "partitions". A partition consists of all rows that have the same value for all terms of the PARTITION BY clause in the <yynonterm>window-defn</yynonterm>. If there is no PARTITION BY clause, then the entire result set of the query is a single partition. Window-function processing is performed separately for each partition. <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> <p> In the query above, the "PARTITION BY c" clause breaks the result set up into three partitions. The first partition has three rows with c=='one'. The second partition has two rows with c=='three' and the third partition has two rows with c=='two'. <p> In the example above, all the rows for each partition are grouped together in the final output. This is because the PARTITION BY clause is a prefix of the ORDER BY clause on the overall query. But that does not have to be the case. A partition can be composed of rows scattered about haphazardly within the result set. 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>-- two | 2 | B | B.E </i> <i>-- three | 3 | C | C.F </i> <i>-- one | 4 | D | D.G </i> <i>-- two | 5 | E | E </i> <i>-- three | 6 | F | F </i> <i>-- one | 7 | G | G </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 a; </codeblock> <tcl>hd_fragment framespec {frame specification} {frames}</tcl> <h2>Frame Specifications</h2> <p> The <yynonterm>frame-spec</yynonterm> determines which output rows are read by an aggregate window function. The <yynonterm>frame-spec</yynonterm> consists of four parts: <ul> <li> A frame type - either ROWS, RANGE or GROUPS, <li> A starting frame boundary, <li> An ending frame boundary, <li> An EXCLUDE clause. </ul> <p> Here are the syntax details: <tcl> RecursiveBubbleDiagram frame-spec </tcl> <p>The ending frame boundary can be omitted (if the BETWEEN and AND keywords that surround the starting frame boundary are also omitted), in which case the ending frame boundary defaults to CURRENT ROW. <p> If the frame type is RANGE or GROUPS, then rows with the same values for all ORDER BY expressions are considered "peers". Or, if there are no ORDER BY terms, all rows are peers. Peers are always within the same frame. <p>The default <yynonterm>frame-spec</yynonterm> is: <codeblock> RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE NO OTHERS </codeblock> |
︙ | ︙ | |||
177 178 179 180 181 182 183 184 | <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> | > > > | > > | > | | | | > > | > > > > > | > | > > | > > | < < < < | > > | > > | < > > > > | | | > | > | > | | > | | > > > > > > > | > > > > > > > > > > > > | > | | > > | | < > > > | > > > > > > > > > > > > > > > > > > > > > | | > | | > | < | > > | > > | | > | | 256 257 258 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 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 | <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> <tcl>hd_fragment frametype {frame type}</tcl> <h3>Frame Type</h3> <p> There are three frame types: ROWS, GROUPS, and RANGE. The frame type determines how the starting and ending boundaries of the frame are measured. <ul> <li><p><b>ROWS</b>: The ROWS frame type means that the starting and ending boundaries for the frame are determined by counting individual rows relative to the current row. <tcl>hd_fragment grouptype {GROUPS frames}</tcl> <li><p><b>GROUPS</b>: The GROUPS frame type means that the starting and ending boundaries are determine by counting "groups" relative to the current group. A "group" is a set of rows that all have equivalent values for all all terms of the window ORDER BY clause. ("Equivalent" means that the [IS operator] is true when comparing the two values.) In other words, a group consists of all peers of a row. <tcl>hd_fragment rangetype {RANGE frames}</tcl> <li><p><b>RANGE</b>: The RANGE frame type requires that the ORDER BY clause of the window have exactly one term. Call that term "X". With the RANGE frame type, the elements of the frame are determined by computing the value of expression X for all rows in the partition and framing those rows for which the value of X is within a certain range of the value of X for the current row. See the description in the "[RANGE n PRECEDING|<expr> PRECEDING]" boundary specification below for details. </ul> <p>The ROWS and GROUPS frame types are similar in that they both determine the extent of a frame by counting relative to the current row. The difference is that ROWS counts individual rows and GROUPS counts peer groups. The RANGE frame type is different. The RANGE frame type determines the extent of a frame by looking for expression values that are within some band of values relative to the current row. <tcl>hd_fragment frameboundary {frame boundary}</tcl> <h3>Frame Boundaries</h3> <p> There are five ways to describe starting and ending frame boundaries: <ol> <li><p> <b>UNBOUNDED PRECEDING</b><br> The frame boundary is the first row in the [partition]. <li><p> <b><expr> PRECEDING</b><br> <expr> must be a non-negative constant numeric expression. The boundary is a row that is <expr> "units" prior to the current row. The meaning of "units" here depends on the frame type: <ul> <li><p> <b>ROWS →</b> The frame boundary is the row that is <expr> rows before the current row, or the first row of the partition if there are fewer than <expr> rows before the current row. <expr> must be an integer. <li><p> <b>GROUPS →</b> A "group" is a set of peer rows - rows that all have the same values for every term in the ORDER BY clause. The frame boundary is the group that is <expr> groups before the group containing the current row, or the first group of the partition if there are fewer than <expr> groups before the current row. For the starting boundary of a frame, the first row of the group is used and for the ending boundary of a frame, the last row of the group is used. <expr> must be an integer. <tcl>hd_fragment exprrange {RANGE n PRECEDING} {RANGE n FOLLOWING}</tcl> <li><p> <b>RANGE →</b> For this form, the ORDER BY clause of the <yynonterm>window-defn</yynonterm> must have a single term. Call that ORDER BY term "X". Let X<sub><small>i</small></sub> be the value of the X expression for the i-th row in the partition and let X<sub><small>c</small></sub> be the value of X for the current row. Informally, a RANGE bound is the first row for which X<sub><small>i</small></sub> is within the <expr> of X<sub><small>c</small></sub>. More precisely: <ol type="a"> <li> If either X<sub><small>i</small></sub> or X<sub><small>c</small></sub> are non-numeric, then the boundary is the first row for which the expression "X<sub><small>i</small></sub> IS X<sub><small>c</small></sub>" is true. <li> Else if the ORDER BY is ASC then the boundary is the first row for which X<sub><small>i</small></sub>>=X<sub><small>c</small></sub>-<expr>. <li> Else if the ORDER BY is DESC then the boundary is the first row for which X<sub><small>i</small></sub><=X<sub><small>c</small></sub>-<expr>. </ol> For this form, the <expr> does not have to be an integer. It can evaluate to a real number as long as it is constant and non-negative. </ul> The boundary description "0 PRECEDING" always means the same thing as "CURRENT ROW". <li><p><b>CURRENT ROW</b><br> The current row. For RANGE and GROUPS frame types, peers of the current row are also included in the frame, unless specifically excluded by the EXCLUDE clause. This is true regardless of whether CURRENT ROW is used as the starting or ending frame boundary. <li><p><b><expr> FOLLOWING</b><br> This is the same as "<expr> PRECEDING" except that the boundary is <expr> units after the current rather than before the current row. <li><p> <b>UNBOUNDED FOLLOWING</b><br> The frame boundary is the last row in the [partition]. </ol> <p> The ending frame boundary may 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> |
︙ | ︙ | |||
253 254 255 256 257 258 259 | <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> | | | < < > > | > > | > > > | > > | | > | > > > | > | < | | | | | | | > | | > > > > > > | > > > | 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 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 | <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> <tcl>hd_fragment wexcls {exclude clause} {EXCLUDE clause}</tcl> <h3>The EXCLUDE Clause</h3> <p> The optional EXCLUDE clause may take any of the following four forms: <ul> <li> <p><b> EXCLUDE NO OTHERS</b>: This is the default. In this case no rows are excluded from the window frame as defined by its starting and ending frame boundaries. <li> <p><b> EXCLUDE CURRENT ROW</b>: In this case the current row is excluded from the window frame. Peers of the current row remain in the frame for the GROUPS and RANGE frame types. <li> <p><b> EXCLUDE GROUP</b>: In this case the current row and all other rows that are peers of the current row are excluded from the frame. When processing an EXCLUDE clause, all rows with the same ORDER BY values, or all rows in the partition if there is no ORDER BY clause, are considered peers, even if the frame type is ROWS. <li> <p><b> EXCLUDE TIES</b>: In this case the current row is part of the frame, but peers of the current row are excluded. </ul> <p> The following example demonstrates the effect of the various forms of the EXCLUDE clause: <codeblock> <i>-- The following SELECT statement returns:</i> <i>-- </i> <i>-- c | a | b | no_others | current_row | grp | ties</i> <i>-- one | 1 | A | A.D.G | D.G | | A</i> <i>-- one | 4 | D | A.D.G | A.G | | D</i> <i>-- one | 7 | G | A.D.G | A.D | | G</i> <i>-- three | 3 | C | A.D.G.C.F | A.D.G.F | A.D.G | A.D.G.C</i> <i>-- three | 6 | F | A.D.G.C.F | A.D.G.C | A.D.G | A.D.G.F</i> <i>-- two | 2 | B | A.D.G.C.F.B.E | A.D.G.C.F.E | A.D.G.C.F | A.D.G.C.F.B</i> <i>-- two | 5 | E | A.D.G.C.F.B.E | A.D.G.C.F.B | A.D.G.C.F | A.D.G.C.F.E</i> <i>-- </i> SELECT c, a, b, group_concat(b, '.') OVER ( ORDER BY c GROUPS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE NO OTHERS ) AS no_others, group_concat(b, '.') OVER ( ORDER BY c GROUPS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE CURRENT ROW ) AS current_row, group_concat(b, '.') OVER ( ORDER BY c GROUPS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE GROUP ) AS grp, group_concat(b, '.') OVER ( ORDER BY c GROUPS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES ) AS ties FROM t1 ORDER BY c, a; </codeblock> <h2>The FILTER Clause</h2> <tcl> RecursiveBubbleDiagram filter |
︙ | ︙ | |||
317 318 319 320 321 322 323 | <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> | < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < | 493 494 495 496 497 498 499 500 501 502 503 504 505 506 | <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> <tcl>hd_fragment wchaining {window chaining}</tcl> <h2>Window Chaining</h2> <p> Window chaining is a shorthand that allows one window to be defined in terms of another. Specifically, the shorthand allows the new window to implicitly |
︙ | ︙ | |||
392 393 394 395 396 397 398 | <p> the window used by the group_concat() is equivalent to "PARTITION BY a ORDER BY c ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW". In order to use window chaining, all of the following must be true: <ul> <li><p>The new window definition must not include a PARTITION BY clause. The | | | | > > | | | 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 | <p> the window used by the group_concat() is equivalent to "PARTITION BY a ORDER BY c ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW". In order to use window chaining, all of the following must be true: <ul> <li><p>The new window definition must not include a PARTITION BY clause. The PARTITION BY clause, if there is one, must be supplied by the base window specification. <li><p>If the base window has an ORDER BY clause, it is copied into the new window. In this case the new window must not specify an ORDER BY clause. If the base window has no ORDER BY clause, one may be specified as part of the new window definition. <li><p>The base window may not specify a frame specification. The frame specification can only be given in the new window specification. </ul> <p>The two fragments of SQL below are similar, but not entirely equivalent, as the latter will fail if the definition of window "win" contains a frame specification. <codeblock> SELECT group_concat(b, '.') OVER win ... SELECT group_concat(b, '.') OVER (win) ... </codeblock> <tcl>hd_fragment builtins {built-in window functions} {built-ins}</tcl> <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 <yynonterm>frame-spec</yynonterm> specifies ROWS, GROUPS, 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 <yynonterm>frame-spec</yynonterm>, 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. |
︙ | ︙ | |||
820 821 822 823 824 825 826 | <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> <h1>History</h1> | | > > > > > > | 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 | <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> <h1>History</h1> <p>Window function support was first added to SQLite with release [version 3.25.0] ([dateof:3.25.0]). The SQLite developers used the <a href=http://www.postgresql.org>PostgreSQL</a> window function documentation as their primary reference for how window functions ought to behave. Many test cases have been run against PostgreSQL to ensure that window functions operate the same way in both SQLite and PostgreSQL. <p>In SQLite [version 3.28.0] ([dateof:3.28.0]), windows function support was extended to include the EXCLUDE clause, GROUPS frame types, window chaining, and support for "<expr> PRECEDING" and "<expr> FOLLOWING" boundaries in RANGE frames. |