Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Improve windowfunctions.in. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA3-256: |
7094fcac7822c37cebfe53176f2537f2 |
User & Date: | dan 2018-06-21 21:00:10.794 |
Context
2018-06-22
| ||
16:14 | Add further examples to windowfunctions.in. (check-in: 84418fef8d user: dan tags: trunk) | |
2018-06-21
| ||
21:00 | Improve windowfunctions.in. (check-in: 7094fcac78 user: dan tags: trunk) | |
2018-06-20
| ||
21:13 | Add beginning of documentation for window functions in new file windowfunctions.in. (check-in: c1e5cf0cb1 user: dan tags: trunk) | |
Changes
Changes to pages/windowfunctions.in.
1 2 3 4 5 6 7 8 9 10 11 12 13 | <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> <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 | > > > | 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 | <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]). <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 |
︙ | ︙ | |||
51 52 53 54 55 56 57 58 59 60 61 62 63 64 | <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"). <h1>Aggregate Window Functions</h1> <p> The examples in this section all assume that the database is populated as follows: <codeblock> | > > > > > > > > > > > > > > > | 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 | <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>Aggregate Window Functions</h1> <p> The examples in this section all assume that the database is populated as follows: <codeblock> |
︙ | ︙ | |||
118 119 120 121 122 123 124 125 126 127 128 129 130 131 | <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) FROM t1 ORDER BY a; </codeblock> <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 | > > > > | 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 | <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) 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 |
︙ | ︙ | |||
157 158 159 160 161 162 163 164 165 166 167 168 | 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> <h2>The PARTITION BY Clause</h2> <h2>The FILTER Clause</h2> | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | > > > > > > > > > > > > > > > | | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 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 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 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 | 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>-- 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 ) 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>-- one |1|A|A</i> <i>-- one |4|D|A.D</i> <i>-- one |7|G|A.D.G</i> <i>-- three|3|C|C</i> <i>-- three|6|F|C.F</i> <i>-- two |2|B|B</i> <i>-- two |5|E|B.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 ) 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>-- one |1|A|A.C.D.F.G</i> <i>-- two |2|B|C.D.F.G</i> <i>-- three|3|C|C.D.F.G</i> <i>-- one |4|D|D.F.G</i> <i>-- two |5|E|F.G</i> <i>-- three|6|F|F.G</i> <i>-- one |7|G|G</i> <i>-- </i> SELECT c, a, b, group_concat(b, '.') FILTER (WHERE c!='two') OVER (ORDER BY a) FROM t1 ORDER BY a; </codeblock> <h2 tags="user-defined window functions">User-Defined Aggregate Window Functions</h2> <p>TODO: Link to C API docs (sqlite3_create_window_function()). <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. <dd> </dl> |