├── .gitattributes ├── .gitignore ├── CODE_OF_CONDUCT.md ├── LICENSE ├── Makefile ├── README.extra_window_functions ├── README.md ├── expected └── regression.out ├── extra_window_functions--1.0.sql ├── extra_window_functions.c ├── extra_window_functions.control ├── open-graph.png └── sql └── regression.sql /.gitattributes: -------------------------------------------------------------------------------- 1 | sql/* linguist-language=SQL 2 | expected/* linguist-detectable=false 3 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | .vscode/ 2 | test_current.sh 3 | .deps/ 4 | extra_window_functions.o 5 | extra_window_functions.so 6 | -------------------------------------------------------------------------------- /CODE_OF_CONDUCT.md: -------------------------------------------------------------------------------- 1 | This extension adheres to the official [PostgreSQL Community Code of 2 | Conduct](https://www.postgresql.org/about/policies/coc/). It is not 3 | reproduced here so that future modifications may take effect 4 | immediately. 5 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | PostgreSQL License 2 | 3 | Copyright (c) 2019, The PostgreSQL Global Development Group (PGDG) 4 | 5 | Permission to use, copy, modify, and distribute this software and its 6 | documentation for any purpose, without fee, and without a written agreement is 7 | hereby granted, provided that the above copyright notice and this paragraph 8 | and the following two paragraphs appear in all copies. 9 | 10 | IN NO EVENT SHALL PGDG BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, 11 | SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING 12 | OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF PGDG 13 | HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 14 | 15 | PGDG SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT 16 | LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A 17 | PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, 18 | AND PGDG HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, 19 | ENHANCEMENTS, OR MODIFICATIONS. 20 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | MODULES = extra_window_functions 2 | EXTENSION = extra_window_functions 3 | DOCS = README.extra_window_functions 4 | 5 | DATA = extra_window_functions--1.0.sql 6 | 7 | REGRESS = regression 8 | 9 | PG_CONFIG = pg_config 10 | PGXS := $(shell $(PG_CONFIG) --pgxs) 11 | include $(PGXS) 12 | -------------------------------------------------------------------------------- /README.extra_window_functions: -------------------------------------------------------------------------------- 1 | README.md -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Extra Window Functions for PostgreSQL 2 | 3 | [![License](https://img.shields.io/badge/license-PostgreSQL-blue)](https://www.postgresql.org/about/licence/) 4 | [![Code of Conduct](https://img.shields.io/badge/code%20of%20conduct-PostgreSQL-blueviolet)](https://www.postgresql.org/about/policies/coc/) 5 | 6 | *compatible 9.6–15* 7 | 8 | This extension provides additional window functions to PostgreSQL. Some of 9 | them provide SQL Standard functionality but without the SQL Standard grammar, 10 | others extend on the SQL Standard, and still others are novel and hopefully 11 | useful to someone. 12 | 13 | ## Simulating Standard SQL 14 | 15 | The window functions `LEAD()`, `LAG()`, `FIRST_VALUE()`, `LAST_VALUE()`, and 16 | `NTH_VALUE()` can skip over null values. PostgreSQL does not implement the 17 | syntax required for that feature but this extension provides additional 18 | functions that give you the same behavior. 19 | 20 | In addition to this, `NTH_VALUE()` can count from the start or the end of the 21 | window frame. 22 | 23 | Functions provided: 24 | 25 | - `lag_ignore_nulls(expression[, offset[, default]])` 26 | - `lead_ignore_nulls(expression[, offset[, default]])` 27 | - `first_value_ignore_nulls(expression)` 28 | - `last_value_ignore_nulls(expression)` 29 | - `nth_value_from_last(expression, offset)` 30 | - `nth_value_ignore_nulls(expression, offset)` 31 | - `nth_value_from_last_ignore_nulls(expression, offset)` 32 | 33 | Despite these functions having long names, there isn't really any difference in 34 | length compared to the excessively verbose SQL Standard syntax. 35 | 36 | ``` 37 | -- Standard SQL: 38 | NTH_VALUE(x, 3) FROM LAST IGNORE NULLS OVER w 39 | 40 | -- This extension: 41 | nth_value_from_last_ignore_nulls(x, 3) OVER w 42 | ``` 43 | 44 | ## Extending Standard SQL 45 | 46 | The functions `LEAD()` and `LAG()` accept a default value for when the 47 | requested row falls outside of the partition. However, the functions 48 | `FIRST_VALUE()`, `LAST_VALUE()`, and `NTH_VALUE()` do not have default values 49 | for when the requested row is not in the frame. 50 | 51 | Functions provided: 52 | 53 | - `first_value_ignore_nulls(expression, default)` 54 | - `last_value_ignore_nulls(expression, default)` 55 | - `nth_value_from_last(expression, offset, default)` 56 | - `nth_value_ignore_nulls(expression, offset, default)` 57 | - `nth_value_from_last_ignore_nulls(expression, offset, default)` 58 | 59 | ## Non-Standard Functions 60 | 61 | This extension introduces a new partition-level window function `flip_flop()` 62 | and implements the 63 | "[flip floperator](https://en.wikipedia.org/wiki/Flip-flop_(programming))". 64 | 65 | In the first variant, the function returns false until the expression given as 66 | an argument returns true. It then keeps returning true until the expression is 67 | matched again. The second variant takes two expressions: the first to flip, 68 | the second to flop. 69 | 70 | Functions provided: 71 | 72 | - `flip_flop(expression[, expression])` 73 | 74 | -------------------------------------------------------------------------------- /expected/regression.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION extra_window_functions; 2 | CREATE TABLE things ( 3 | part integer NOT NULL, 4 | ord integer NOT NULL, 5 | val integer 6 | ); 7 | COPY things FROM stdin; 8 | /* FLIP_FLOP */ 9 | SELECT part, ord, val, 10 | flip_flop(val % 2 = 0) OVER w AS flip_flop_1, 11 | flip_flop(val % 2 = 0, val % 2 = 1) OVER w AS flip_flop_2 12 | FROM things 13 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 14 | ORDER BY part, ord; 15 | part | ord | val | flip_flop_1 | flip_flop_2 16 | ------+-----+-------+-------------+------------- 17 | 1 | 1 | 64664 | t | t 18 | 1 | 2 | 8779 | t | t 19 | 1 | 3 | 14005 | t | f 20 | 1 | 4 | 57699 | t | f 21 | 1 | 5 | 98842 | t | t 22 | 1 | 6 | 88563 | f | t 23 | 1 | 7 | 70453 | f | f 24 | 1 | 8 | 82824 | t | t 25 | 1 | 9 | 62453 | t | t 26 | 2 | 1 | | f | f 27 | 2 | 2 | 51714 | t | t 28 | 2 | 3 | 17096 | t | t 29 | 2 | 4 | 41605 | f | t 30 | 2 | 5 | 15366 | t | t 31 | 2 | 6 | 87359 | t | t 32 | 2 | 7 | 98990 | t | t 33 | 2 | 8 | 34982 | t | t 34 | 2 | 9 | 3343 | t | t 35 | 3 | 1 | 21903 | f | f 36 | 3 | 2 | 24605 | f | f 37 | 3 | 3 | 6242 | t | t 38 | 3 | 4 | 24947 | t | t 39 | 3 | 5 | 79535 | t | f 40 | 3 | 6 | 66903 | t | f 41 | 3 | 7 | 42269 | t | f 42 | 3 | 8 | 31143 | t | f 43 | 3 | 9 | | t | f 44 | 4 | 1 | | f | f 45 | 4 | 2 | 49723 | f | f 46 | 4 | 3 | 23958 | t | t 47 | 4 | 4 | 80796 | t | t 48 | 4 | 5 | | f | t 49 | 4 | 6 | 41066 | t | t 50 | 4 | 7 | 72991 | t | t 51 | 4 | 8 | 33734 | t | t 52 | 4 | 9 | | f | t 53 | 5 | 1 | | f | f 54 | 5 | 2 | | f | f 55 | 5 | 3 | | f | f 56 | 5 | 4 | | f | f 57 | 5 | 5 | | f | f 58 | 5 | 6 | | f | f 59 | 5 | 7 | | f | f 60 | 5 | 8 | | f | f 61 | 5 | 9 | | f | f 62 | (45 rows) 63 | 64 | /* LAG */ 65 | SELECT part, ord, val, 66 | lag(val) OVER w AS lag, 67 | lag_ignore_nulls(val) OVER w AS lag_in, 68 | lag_ignore_nulls(val, 2) OVER w AS lag_in_off, 69 | lag_ignore_nulls(val, 2, -9999999) OVER w AS lag_in_off_d 70 | FROM things 71 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 72 | ORDER BY part, ord; 73 | part | ord | val | lag | lag_in | lag_in_off | lag_in_off_d 74 | ------+-----+-------+-------+--------+------------+-------------- 75 | 1 | 1 | 64664 | | | | -9999999 76 | 1 | 2 | 8779 | 64664 | 64664 | | -9999999 77 | 1 | 3 | 14005 | 8779 | 8779 | 64664 | 64664 78 | 1 | 4 | 57699 | 14005 | 14005 | 8779 | 8779 79 | 1 | 5 | 98842 | 57699 | 57699 | 14005 | 14005 80 | 1 | 6 | 88563 | 98842 | 98842 | 57699 | 57699 81 | 1 | 7 | 70453 | 88563 | 88563 | 98842 | 98842 82 | 1 | 8 | 82824 | 70453 | 70453 | 88563 | 88563 83 | 1 | 9 | 62453 | 82824 | 82824 | 70453 | 70453 84 | 2 | 1 | | | | | -9999999 85 | 2 | 2 | 51714 | | | | -9999999 86 | 2 | 3 | 17096 | 51714 | 51714 | | -9999999 87 | 2 | 4 | 41605 | 17096 | 17096 | 51714 | 51714 88 | 2 | 5 | 15366 | 41605 | 41605 | 17096 | 17096 89 | 2 | 6 | 87359 | 15366 | 15366 | 41605 | 41605 90 | 2 | 7 | 98990 | 87359 | 87359 | 15366 | 15366 91 | 2 | 8 | 34982 | 98990 | 98990 | 87359 | 87359 92 | 2 | 9 | 3343 | 34982 | 34982 | 98990 | 98990 93 | 3 | 1 | 21903 | | | | -9999999 94 | 3 | 2 | 24605 | 21903 | 21903 | | -9999999 95 | 3 | 3 | 6242 | 24605 | 24605 | 21903 | 21903 96 | 3 | 4 | 24947 | 6242 | 6242 | 24605 | 24605 97 | 3 | 5 | 79535 | 24947 | 24947 | 6242 | 6242 98 | 3 | 6 | 66903 | 79535 | 79535 | 24947 | 24947 99 | 3 | 7 | 42269 | 66903 | 66903 | 79535 | 79535 100 | 3 | 8 | 31143 | 42269 | 42269 | 66903 | 66903 101 | 3 | 9 | | 31143 | 31143 | 42269 | 42269 102 | 4 | 1 | | | | | -9999999 103 | 4 | 2 | 49723 | | | | -9999999 104 | 4 | 3 | 23958 | 49723 | 49723 | | -9999999 105 | 4 | 4 | 80796 | 23958 | 23958 | 49723 | 49723 106 | 4 | 5 | | 80796 | 80796 | 23958 | 23958 107 | 4 | 6 | 41066 | | 80796 | 23958 | 23958 108 | 4 | 7 | 72991 | 41066 | 41066 | 80796 | 80796 109 | 4 | 8 | 33734 | 72991 | 72991 | 41066 | 41066 110 | 4 | 9 | | 33734 | 33734 | 72991 | 72991 111 | 5 | 1 | | | | | -9999999 112 | 5 | 2 | | | | | -9999999 113 | 5 | 3 | | | | | -9999999 114 | 5 | 4 | | | | | -9999999 115 | 5 | 5 | | | | | -9999999 116 | 5 | 6 | | | | | -9999999 117 | 5 | 7 | | | | | -9999999 118 | 5 | 8 | | | | | -9999999 119 | 5 | 9 | | | | | -9999999 120 | (45 rows) 121 | 122 | /* LEAD */ 123 | SELECT part, ord, val, 124 | lead(val) OVER w AS lead, 125 | lead_ignore_nulls(val) OVER w AS lead_in, 126 | lead_ignore_nulls(val, 2) OVER w AS lead_in_off, 127 | lead_ignore_nulls(val, 2, 9999999) OVER w AS lead_in_off_d 128 | FROM things 129 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 130 | ORDER BY part, ord; 131 | part | ord | val | lead | lead_in | lead_in_off | lead_in_off_d 132 | ------+-----+-------+-------+---------+-------------+--------------- 133 | 1 | 1 | 64664 | 8779 | 8779 | 14005 | 14005 134 | 1 | 2 | 8779 | 14005 | 14005 | 57699 | 57699 135 | 1 | 3 | 14005 | 57699 | 57699 | 98842 | 98842 136 | 1 | 4 | 57699 | 98842 | 98842 | 88563 | 88563 137 | 1 | 5 | 98842 | 88563 | 88563 | 70453 | 70453 138 | 1 | 6 | 88563 | 70453 | 70453 | 82824 | 82824 139 | 1 | 7 | 70453 | 82824 | 82824 | 62453 | 62453 140 | 1 | 8 | 82824 | 62453 | 62453 | | 9999999 141 | 1 | 9 | 62453 | | | | 9999999 142 | 2 | 1 | | 51714 | 51714 | 17096 | 17096 143 | 2 | 2 | 51714 | 17096 | 17096 | 41605 | 41605 144 | 2 | 3 | 17096 | 41605 | 41605 | 15366 | 15366 145 | 2 | 4 | 41605 | 15366 | 15366 | 87359 | 87359 146 | 2 | 5 | 15366 | 87359 | 87359 | 98990 | 98990 147 | 2 | 6 | 87359 | 98990 | 98990 | 34982 | 34982 148 | 2 | 7 | 98990 | 34982 | 34982 | 3343 | 3343 149 | 2 | 8 | 34982 | 3343 | 3343 | | 9999999 150 | 2 | 9 | 3343 | | | | 9999999 151 | 3 | 1 | 21903 | 24605 | 24605 | 6242 | 6242 152 | 3 | 2 | 24605 | 6242 | 6242 | 24947 | 24947 153 | 3 | 3 | 6242 | 24947 | 24947 | 79535 | 79535 154 | 3 | 4 | 24947 | 79535 | 79535 | 66903 | 66903 155 | 3 | 5 | 79535 | 66903 | 66903 | 42269 | 42269 156 | 3 | 6 | 66903 | 42269 | 42269 | 31143 | 31143 157 | 3 | 7 | 42269 | 31143 | 31143 | | 9999999 158 | 3 | 8 | 31143 | | | | 9999999 159 | 3 | 9 | | | | | 9999999 160 | 4 | 1 | | 49723 | 49723 | 23958 | 23958 161 | 4 | 2 | 49723 | 23958 | 23958 | 80796 | 80796 162 | 4 | 3 | 23958 | 80796 | 80796 | 41066 | 41066 163 | 4 | 4 | 80796 | | 41066 | 72991 | 72991 164 | 4 | 5 | | 41066 | 41066 | 72991 | 72991 165 | 4 | 6 | 41066 | 72991 | 72991 | 33734 | 33734 166 | 4 | 7 | 72991 | 33734 | 33734 | | 9999999 167 | 4 | 8 | 33734 | | | | 9999999 168 | 4 | 9 | | | | | 9999999 169 | 5 | 1 | | | | | 9999999 170 | 5 | 2 | | | | | 9999999 171 | 5 | 3 | | | | | 9999999 172 | 5 | 4 | | | | | 9999999 173 | 5 | 5 | | | | | 9999999 174 | 5 | 6 | | | | | 9999999 175 | 5 | 7 | | | | | 9999999 176 | 5 | 8 | | | | | 9999999 177 | 5 | 9 | | | | | 9999999 178 | (45 rows) 179 | 180 | /* FIRST_VALUE */ 181 | SELECT part, ord, val, 182 | first_value(val) OVER w AS fv, 183 | first_value_ignore_nulls(val) OVER w AS fv_in, 184 | first_value_ignore_nulls(val, 9999999) OVER w AS fv_in_d 185 | FROM things 186 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 187 | ORDER BY part, ord; 188 | part | ord | val | fv | fv_in | fv_in_d 189 | ------+-----+-------+-------+-------+--------- 190 | 1 | 1 | 64664 | 64664 | 64664 | 64664 191 | 1 | 2 | 8779 | 64664 | 64664 | 64664 192 | 1 | 3 | 14005 | 64664 | 64664 | 64664 193 | 1 | 4 | 57699 | 8779 | 8779 | 8779 194 | 1 | 5 | 98842 | 14005 | 14005 | 14005 195 | 1 | 6 | 88563 | 57699 | 57699 | 57699 196 | 1 | 7 | 70453 | 98842 | 98842 | 98842 197 | 1 | 8 | 82824 | 88563 | 88563 | 88563 198 | 1 | 9 | 62453 | 70453 | 70453 | 70453 199 | 2 | 1 | | | 51714 | 51714 200 | 2 | 2 | 51714 | | 51714 | 51714 201 | 2 | 3 | 17096 | | 51714 | 51714 202 | 2 | 4 | 41605 | 51714 | 51714 | 51714 203 | 2 | 5 | 15366 | 17096 | 17096 | 17096 204 | 2 | 6 | 87359 | 41605 | 41605 | 41605 205 | 2 | 7 | 98990 | 15366 | 15366 | 15366 206 | 2 | 8 | 34982 | 87359 | 87359 | 87359 207 | 2 | 9 | 3343 | 98990 | 98990 | 98990 208 | 3 | 1 | 21903 | 21903 | 21903 | 21903 209 | 3 | 2 | 24605 | 21903 | 21903 | 21903 210 | 3 | 3 | 6242 | 21903 | 21903 | 21903 211 | 3 | 4 | 24947 | 24605 | 24605 | 24605 212 | 3 | 5 | 79535 | 6242 | 6242 | 6242 213 | 3 | 6 | 66903 | 24947 | 24947 | 24947 214 | 3 | 7 | 42269 | 79535 | 79535 | 79535 215 | 3 | 8 | 31143 | 66903 | 66903 | 66903 216 | 3 | 9 | | 42269 | 42269 | 42269 217 | 4 | 1 | | | 49723 | 49723 218 | 4 | 2 | 49723 | | 49723 | 49723 219 | 4 | 3 | 23958 | | 49723 | 49723 220 | 4 | 4 | 80796 | 49723 | 49723 | 49723 221 | 4 | 5 | | 23958 | 23958 | 23958 222 | 4 | 6 | 41066 | 80796 | 80796 | 80796 223 | 4 | 7 | 72991 | | 41066 | 41066 224 | 4 | 8 | 33734 | 41066 | 41066 | 41066 225 | 4 | 9 | | 72991 | 72991 | 72991 226 | 5 | 1 | | | | 9999999 227 | 5 | 2 | | | | 9999999 228 | 5 | 3 | | | | 9999999 229 | 5 | 4 | | | | 9999999 230 | 5 | 5 | | | | 9999999 231 | 5 | 6 | | | | 9999999 232 | 5 | 7 | | | | 9999999 233 | 5 | 8 | | | | 9999999 234 | 5 | 9 | | | | 9999999 235 | (45 rows) 236 | 237 | /* LAST_VALUE */ 238 | SELECT part, ord, val, 239 | last_value(val) OVER w AS lv, 240 | last_value_ignore_nulls(val) OVER w AS lv_in, 241 | last_value_ignore_nulls(val, -9999999) OVER w AS lv_in_d 242 | FROM things 243 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 244 | ORDER BY part, ord; 245 | part | ord | val | lv | lv_in | lv_in_d 246 | ------+-----+-------+-------+-------+---------- 247 | 1 | 1 | 64664 | 14005 | 14005 | 14005 248 | 1 | 2 | 8779 | 57699 | 57699 | 57699 249 | 1 | 3 | 14005 | 98842 | 98842 | 98842 250 | 1 | 4 | 57699 | 88563 | 88563 | 88563 251 | 1 | 5 | 98842 | 70453 | 70453 | 70453 252 | 1 | 6 | 88563 | 82824 | 82824 | 82824 253 | 1 | 7 | 70453 | 62453 | 62453 | 62453 254 | 1 | 8 | 82824 | 62453 | 62453 | 62453 255 | 1 | 9 | 62453 | 62453 | 62453 | 62453 256 | 2 | 1 | | 17096 | 17096 | 17096 257 | 2 | 2 | 51714 | 41605 | 41605 | 41605 258 | 2 | 3 | 17096 | 15366 | 15366 | 15366 259 | 2 | 4 | 41605 | 87359 | 87359 | 87359 260 | 2 | 5 | 15366 | 98990 | 98990 | 98990 261 | 2 | 6 | 87359 | 34982 | 34982 | 34982 262 | 2 | 7 | 98990 | 3343 | 3343 | 3343 263 | 2 | 8 | 34982 | 3343 | 3343 | 3343 264 | 2 | 9 | 3343 | 3343 | 3343 | 3343 265 | 3 | 1 | 21903 | 6242 | 6242 | 6242 266 | 3 | 2 | 24605 | 24947 | 24947 | 24947 267 | 3 | 3 | 6242 | 79535 | 79535 | 79535 268 | 3 | 4 | 24947 | 66903 | 66903 | 66903 269 | 3 | 5 | 79535 | 42269 | 42269 | 42269 270 | 3 | 6 | 66903 | 31143 | 31143 | 31143 271 | 3 | 7 | 42269 | | 31143 | 31143 272 | 3 | 8 | 31143 | | 31143 | 31143 273 | 3 | 9 | | | 31143 | 31143 274 | 4 | 1 | | 23958 | 23958 | 23958 275 | 4 | 2 | 49723 | 80796 | 80796 | 80796 276 | 4 | 3 | 23958 | | 80796 | 80796 277 | 4 | 4 | 80796 | 41066 | 41066 | 41066 278 | 4 | 5 | | 72991 | 72991 | 72991 279 | 4 | 6 | 41066 | 33734 | 33734 | 33734 280 | 4 | 7 | 72991 | | 33734 | 33734 281 | 4 | 8 | 33734 | | 33734 | 33734 282 | 4 | 9 | | | 33734 | 33734 283 | 5 | 1 | | | | -9999999 284 | 5 | 2 | | | | -9999999 285 | 5 | 3 | | | | -9999999 286 | 5 | 4 | | | | -9999999 287 | 5 | 5 | | | | -9999999 288 | 5 | 6 | | | | -9999999 289 | 5 | 7 | | | | -9999999 290 | 5 | 8 | | | | -9999999 291 | 5 | 9 | | | | -9999999 292 | (45 rows) 293 | 294 | /* NTH_VALUE */ 295 | SELECT part, ord, val, 296 | nth_value(val, 3) OVER w AS nth, 297 | nth_value_ignore_nulls(val, 3) OVER w AS nth_in 298 | FROM things 299 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 300 | ORDER BY part, ord; 301 | part | ord | val | nth | nth_in 302 | ------+-----+-------+-------+-------- 303 | 1 | 1 | 64664 | 14005 | 14005 304 | 1 | 2 | 8779 | 14005 | 14005 305 | 1 | 3 | 14005 | 14005 | 14005 306 | 1 | 4 | 57699 | 57699 | 57699 307 | 1 | 5 | 98842 | 98842 | 98842 308 | 1 | 6 | 88563 | 88563 | 88563 309 | 1 | 7 | 70453 | 70453 | 70453 310 | 1 | 8 | 82824 | 82824 | 82824 311 | 1 | 9 | 62453 | 62453 | 62453 312 | 2 | 1 | | 17096 | 313 | 2 | 2 | 51714 | 17096 | 41605 314 | 2 | 3 | 17096 | 17096 | 41605 315 | 2 | 4 | 41605 | 41605 | 41605 316 | 2 | 5 | 15366 | 15366 | 15366 317 | 2 | 6 | 87359 | 87359 | 87359 318 | 2 | 7 | 98990 | 98990 | 98990 319 | 2 | 8 | 34982 | 34982 | 34982 320 | 2 | 9 | 3343 | 3343 | 3343 321 | 3 | 1 | 21903 | 6242 | 6242 322 | 3 | 2 | 24605 | 6242 | 6242 323 | 3 | 3 | 6242 | 6242 | 6242 324 | 3 | 4 | 24947 | 24947 | 24947 325 | 3 | 5 | 79535 | 79535 | 79535 326 | 3 | 6 | 66903 | 66903 | 66903 327 | 3 | 7 | 42269 | 42269 | 42269 328 | 3 | 8 | 31143 | 31143 | 31143 329 | 3 | 9 | | | 330 | 4 | 1 | | 23958 | 331 | 4 | 2 | 49723 | 23958 | 80796 332 | 4 | 3 | 23958 | 23958 | 80796 333 | 4 | 4 | 80796 | 80796 | 80796 334 | 4 | 5 | | | 41066 335 | 4 | 6 | 41066 | 41066 | 72991 336 | 4 | 7 | 72991 | 72991 | 33734 337 | 4 | 8 | 33734 | 33734 | 33734 338 | 4 | 9 | | | 339 | 5 | 1 | | | 340 | 5 | 2 | | | 341 | 5 | 3 | | | 342 | 5 | 4 | | | 343 | 5 | 5 | | | 344 | 5 | 6 | | | 345 | 5 | 7 | | | 346 | 5 | 8 | | | 347 | 5 | 9 | | | 348 | (45 rows) 349 | 350 | SELECT part, ord, val, 351 | nth_value(val, 3) OVER w AS nth, 352 | nth_value_from_last(val, 3) OVER w AS nth_fl 353 | FROM things 354 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 355 | ORDER BY part, ord; 356 | part | ord | val | nth | nth_fl 357 | ------+-----+-------+-------+-------- 358 | 1 | 1 | 64664 | 14005 | 64664 359 | 1 | 2 | 8779 | 14005 | 8779 360 | 1 | 3 | 14005 | 14005 | 14005 361 | 1 | 4 | 57699 | 57699 | 57699 362 | 1 | 5 | 98842 | 98842 | 98842 363 | 1 | 6 | 88563 | 88563 | 88563 364 | 1 | 7 | 70453 | 70453 | 70453 365 | 1 | 8 | 82824 | 82824 | 70453 366 | 1 | 9 | 62453 | 62453 | 70453 367 | 2 | 1 | | 17096 | 368 | 2 | 2 | 51714 | 17096 | 51714 369 | 2 | 3 | 17096 | 17096 | 17096 370 | 2 | 4 | 41605 | 41605 | 41605 371 | 2 | 5 | 15366 | 15366 | 15366 372 | 2 | 6 | 87359 | 87359 | 87359 373 | 2 | 7 | 98990 | 98990 | 98990 374 | 2 | 8 | 34982 | 34982 | 98990 375 | 2 | 9 | 3343 | 3343 | 98990 376 | 3 | 1 | 21903 | 6242 | 21903 377 | 3 | 2 | 24605 | 6242 | 24605 378 | 3 | 3 | 6242 | 6242 | 6242 379 | 3 | 4 | 24947 | 24947 | 24947 380 | 3 | 5 | 79535 | 79535 | 79535 381 | 3 | 6 | 66903 | 66903 | 66903 382 | 3 | 7 | 42269 | 42269 | 42269 383 | 3 | 8 | 31143 | 31143 | 42269 384 | 3 | 9 | | | 42269 385 | 4 | 1 | | 23958 | 386 | 4 | 2 | 49723 | 23958 | 49723 387 | 4 | 3 | 23958 | 23958 | 23958 388 | 4 | 4 | 80796 | 80796 | 80796 389 | 4 | 5 | | | 390 | 4 | 6 | 41066 | 41066 | 41066 391 | 4 | 7 | 72991 | 72991 | 72991 392 | 4 | 8 | 33734 | 33734 | 72991 393 | 4 | 9 | | | 72991 394 | 5 | 1 | | | 395 | 5 | 2 | | | 396 | 5 | 3 | | | 397 | 5 | 4 | | | 398 | 5 | 5 | | | 399 | 5 | 6 | | | 400 | 5 | 7 | | | 401 | 5 | 8 | | | 402 | 5 | 9 | | | 403 | (45 rows) 404 | 405 | SELECT part, ord, val, 406 | nth_value_from_last(val, 3) OVER w AS nth_fl, 407 | nth_value_from_last_ignore_nulls(val, 3) OVER w AS nth_fl_in 408 | FROM things 409 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 410 | ORDER BY part, ord; 411 | part | ord | val | nth_fl | nth_fl_in 412 | ------+-----+-------+--------+----------- 413 | 1 | 1 | 64664 | 64664 | 64664 414 | 1 | 2 | 8779 | 8779 | 8779 415 | 1 | 3 | 14005 | 14005 | 14005 416 | 1 | 4 | 57699 | 57699 | 57699 417 | 1 | 5 | 98842 | 98842 | 98842 418 | 1 | 6 | 88563 | 88563 | 88563 419 | 1 | 7 | 70453 | 70453 | 70453 420 | 1 | 8 | 82824 | 70453 | 70453 421 | 1 | 9 | 62453 | 70453 | 70453 422 | 2 | 1 | | | 423 | 2 | 2 | 51714 | 51714 | 51714 424 | 2 | 3 | 17096 | 17096 | 17096 425 | 2 | 4 | 41605 | 41605 | 41605 426 | 2 | 5 | 15366 | 15366 | 15366 427 | 2 | 6 | 87359 | 87359 | 87359 428 | 2 | 7 | 98990 | 98990 | 98990 429 | 2 | 8 | 34982 | 98990 | 98990 430 | 2 | 9 | 3343 | 98990 | 98990 431 | 3 | 1 | 21903 | 21903 | 21903 432 | 3 | 2 | 24605 | 24605 | 24605 433 | 3 | 3 | 6242 | 6242 | 6242 434 | 3 | 4 | 24947 | 24947 | 24947 435 | 3 | 5 | 79535 | 79535 | 79535 436 | 3 | 6 | 66903 | 66903 | 66903 437 | 3 | 7 | 42269 | 42269 | 66903 438 | 3 | 8 | 31143 | 42269 | 66903 439 | 3 | 9 | | 42269 | 440 | 4 | 1 | | | 441 | 4 | 2 | 49723 | 49723 | 49723 442 | 4 | 3 | 23958 | 23958 | 49723 443 | 4 | 4 | 80796 | 80796 | 23958 444 | 4 | 5 | | | 80796 445 | 4 | 6 | 41066 | 41066 | 41066 446 | 4 | 7 | 72991 | 72991 | 41066 447 | 4 | 8 | 33734 | 72991 | 41066 448 | 4 | 9 | | 72991 | 449 | 5 | 1 | | | 450 | 5 | 2 | | | 451 | 5 | 3 | | | 452 | 5 | 4 | | | 453 | 5 | 5 | | | 454 | 5 | 6 | | | 455 | 5 | 7 | | | 456 | 5 | 8 | | | 457 | 5 | 9 | | | 458 | (45 rows) 459 | 460 | DROP TABLE things; 461 | DROP EXTENSION extra_window_functions; 462 | -------------------------------------------------------------------------------- /extra_window_functions--1.0.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION extra_window_functions" to load this file. \quit 3 | 4 | /* LAG */ 5 | 6 | CREATE OR REPLACE FUNCTION lag_ignore_nulls(anyelement) 7 | RETURNS anyelement 8 | LANGUAGE c 9 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 10 | AS 'MODULE_PATHNAME', 'window_lag_ignore_nulls'; 11 | 12 | CREATE OR REPLACE FUNCTION lag_ignore_nulls(anyelement, integer) 13 | RETURNS anyelement 14 | LANGUAGE c 15 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 16 | AS 'MODULE_PATHNAME', 'window_lag_ignore_nulls_with_offset'; 17 | 18 | CREATE OR REPLACE FUNCTION lag_ignore_nulls(anyelement, integer, anyelement) 19 | RETURNS anyelement 20 | LANGUAGE c 21 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 22 | AS 'MODULE_PATHNAME', 'window_lag_ignore_nulls_with_offset_with_default'; 23 | 24 | /* LEAD */ 25 | 26 | CREATE OR REPLACE FUNCTION lead_ignore_nulls(anyelement) 27 | RETURNS anyelement 28 | LANGUAGE c 29 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 30 | AS 'MODULE_PATHNAME', 'window_lead_ignore_nulls'; 31 | 32 | CREATE OR REPLACE FUNCTION lead_ignore_nulls(anyelement, integer) 33 | RETURNS anyelement 34 | LANGUAGE c 35 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 36 | AS 'MODULE_PATHNAME', 'window_lead_ignore_nulls_with_offset'; 37 | 38 | CREATE OR REPLACE FUNCTION lead_ignore_nulls(anyelement, integer, anyelement) 39 | RETURNS anyelement 40 | LANGUAGE c 41 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 42 | AS 'MODULE_PATHNAME', 'window_lead_ignore_nulls_with_offset_with_default'; 43 | 44 | /* FIRST_VALUE */ 45 | 46 | CREATE OR REPLACE FUNCTION first_value_ignore_nulls(anyelement) 47 | RETURNS anyelement 48 | LANGUAGE c 49 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 50 | AS 'MODULE_PATHNAME', 'window_first_value_ignore_nulls'; 51 | 52 | CREATE OR REPLACE FUNCTION first_value_ignore_nulls(anyelement, anyelement) 53 | RETURNS anyelement 54 | LANGUAGE c 55 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 56 | AS 'MODULE_PATHNAME', 'window_first_value_ignore_nulls_with_default'; 57 | 58 | /* LAST_VALUE */ 59 | 60 | CREATE OR REPLACE FUNCTION last_value_ignore_nulls(anyelement) 61 | RETURNS anyelement 62 | LANGUAGE c 63 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 64 | AS 'MODULE_PATHNAME', 'window_last_value_ignore_nulls'; 65 | 66 | CREATE OR REPLACE FUNCTION last_value_ignore_nulls(anyelement, anyelement) 67 | RETURNS anyelement 68 | LANGUAGE c 69 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 70 | AS 'MODULE_PATHNAME', 'window_last_value_ignore_nulls_with_default'; 71 | 72 | /* NTH_VALUE */ 73 | 74 | CREATE OR REPLACE FUNCTION nth_value(anyelement, integer, anyelement) 75 | RETURNS anyelement 76 | LANGUAGE c 77 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 78 | AS 'MODULE_PATHNAME', 'window_nth_value_with_default'; 79 | 80 | CREATE OR REPLACE FUNCTION nth_value_from_last(anyelement, integer) 81 | RETURNS anyelement 82 | LANGUAGE c 83 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 84 | AS 'MODULE_PATHNAME', 'window_nth_value_from_last'; 85 | 86 | CREATE OR REPLACE FUNCTION nth_value_from_last_ignore_nulls(anyelement, integer) 87 | RETURNS anyelement 88 | LANGUAGE c 89 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 90 | AS 'MODULE_PATHNAME', 'window_nth_value_from_last_ignore_nulls'; 91 | 92 | CREATE OR REPLACE FUNCTION nth_value_from_last_ignore_nulls(anyelement, integer, anyelement) 93 | RETURNS anyelement 94 | LANGUAGE c 95 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 96 | AS 'MODULE_PATHNAME', 'window_nth_value_from_last_ignore_nulls_with_default'; 97 | 98 | CREATE OR REPLACE FUNCTION nth_value_from_last(anyelement, integer, anyelement) 99 | RETURNS anyelement 100 | LANGUAGE c 101 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 102 | AS 'MODULE_PATHNAME', 'window_nth_value_from_last_with_default'; 103 | 104 | CREATE OR REPLACE FUNCTION nth_value_ignore_nulls(anyelement, integer) 105 | RETURNS anyelement 106 | LANGUAGE c 107 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 108 | AS 'MODULE_PATHNAME', 'window_nth_value_ignore_nulls'; 109 | 110 | CREATE OR REPLACE FUNCTION nth_value_ignore_nulls(anyelement, integer, anyelement) 111 | RETURNS anyelement 112 | LANGUAGE c 113 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 114 | AS 'MODULE_PATHNAME', 'window_nth_value_ignore_nulls_with_default'; 115 | 116 | /* FLIP_FLOP */ 117 | 118 | CREATE OR REPLACE FUNCTION flip_flop(boolean) 119 | RETURNS boolean 120 | LANGUAGE c 121 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 122 | AS 'MODULE_PATHNAME', 'window_flip_flop_1'; 123 | 124 | CREATE OR REPLACE FUNCTION flip_flop(boolean, boolean) 125 | RETURNS boolean 126 | LANGUAGE c 127 | WINDOW IMMUTABLE PARALLEL SAFE STRICT 128 | AS 'MODULE_PATHNAME', 'window_flip_flop_2'; 129 | -------------------------------------------------------------------------------- /extra_window_functions.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | #include "fmgr.h" 3 | 4 | #include "windowapi.h" 5 | 6 | PG_MODULE_MAGIC; 7 | 8 | PG_FUNCTION_INFO_V1(window_lag_ignore_nulls); 9 | PG_FUNCTION_INFO_V1(window_lag_ignore_nulls_with_offset); 10 | PG_FUNCTION_INFO_V1(window_lag_ignore_nulls_with_offset_with_default); 11 | 12 | PG_FUNCTION_INFO_V1(window_lead_ignore_nulls); 13 | PG_FUNCTION_INFO_V1(window_lead_ignore_nulls_with_offset); 14 | PG_FUNCTION_INFO_V1(window_lead_ignore_nulls_with_offset_with_default); 15 | 16 | PG_FUNCTION_INFO_V1(window_first_value_ignore_nulls); 17 | PG_FUNCTION_INFO_V1(window_first_value_ignore_nulls_with_default); 18 | 19 | PG_FUNCTION_INFO_V1(window_last_value_ignore_nulls); 20 | PG_FUNCTION_INFO_V1(window_last_value_ignore_nulls_with_default); 21 | 22 | PG_FUNCTION_INFO_V1(window_nth_value_from_last); 23 | PG_FUNCTION_INFO_V1(window_nth_value_from_last_ignore_nulls); 24 | PG_FUNCTION_INFO_V1(window_nth_value_from_last_ignore_nulls_with_default); 25 | PG_FUNCTION_INFO_V1(window_nth_value_from_last_with_default); 26 | PG_FUNCTION_INFO_V1(window_nth_value_ignore_nulls); 27 | PG_FUNCTION_INFO_V1(window_nth_value_ignore_nulls_with_default); 28 | PG_FUNCTION_INFO_V1(window_nth_value_with_default); 29 | 30 | PG_FUNCTION_INFO_V1(window_flip_flop_1); 31 | PG_FUNCTION_INFO_V1(window_flip_flop_2); 32 | 33 | typedef struct flip_flop_context 34 | { 35 | bool flip_flop; 36 | } flip_flop_context; 37 | 38 | /* LEAD / LAG COMMON */ 39 | 40 | static Datum 41 | lead_lag_common( 42 | FunctionCallInfo fcinfo, 43 | bool forward, bool with_offset, bool with_default) 44 | { 45 | WindowObject winobj = PG_WINDOW_OBJECT(); 46 | int32 offset; 47 | /*bool const_offset;*/ 48 | Datum result; 49 | bool isnull; 50 | bool isout; 51 | int step = forward ? 1 : -1; 52 | int runner = step; 53 | 54 | if (with_offset) 55 | { 56 | offset = DatumGetInt32(WinGetFuncArgCurrent(winobj, 1, &isnull)); 57 | if (isnull) 58 | PG_RETURN_NULL(); 59 | } 60 | else 61 | offset = 1; 62 | 63 | if (!forward) 64 | offset = -offset; 65 | 66 | if (offset == 0) 67 | runner = 0; 68 | 69 | for (;;) 70 | { 71 | result = WinGetFuncArgInPartition(winobj, 0, 72 | runner, 73 | WINDOW_SEEK_CURRENT, 74 | false, 75 | &isnull, &isout); 76 | 77 | if (isout) 78 | break; 79 | 80 | if (isnull) 81 | offset += step; 82 | 83 | if (runner == offset) 84 | break; 85 | 86 | runner += step; 87 | } 88 | 89 | if (isout) 90 | { 91 | /* 92 | * target row is out of the partition; supply default value if 93 | * provided. otherwise it'll stay NULL 94 | */ 95 | if (with_default) 96 | result = WinGetFuncArgCurrent(winobj, 2, &isnull); 97 | } 98 | 99 | if (isnull) 100 | PG_RETURN_NULL(); 101 | 102 | PG_RETURN_DATUM(result); 103 | } 104 | 105 | Datum 106 | window_lag_ignore_nulls(PG_FUNCTION_ARGS) 107 | { 108 | return lead_lag_common(fcinfo, false, false, false); 109 | } 110 | 111 | Datum 112 | window_lag_ignore_nulls_with_offset(PG_FUNCTION_ARGS) 113 | { 114 | return lead_lag_common(fcinfo, false, true, false); 115 | } 116 | 117 | Datum 118 | window_lag_ignore_nulls_with_offset_with_default(PG_FUNCTION_ARGS) 119 | { 120 | return lead_lag_common(fcinfo, false, true, true); 121 | } 122 | 123 | Datum 124 | window_lead_ignore_nulls(PG_FUNCTION_ARGS) 125 | { 126 | return lead_lag_common(fcinfo, true, false, false); 127 | } 128 | 129 | Datum 130 | window_lead_ignore_nulls_with_offset(PG_FUNCTION_ARGS) 131 | { 132 | return lead_lag_common(fcinfo, true, true, false); 133 | } 134 | 135 | Datum 136 | window_lead_ignore_nulls_with_offset_with_default(PG_FUNCTION_ARGS) 137 | { 138 | return lead_lag_common(fcinfo, true, true, true); 139 | } 140 | 141 | /* FIRST_VALUE / LAST_VALUE COMMON */ 142 | 143 | static Datum 144 | first_last_value_common( 145 | FunctionCallInfo fcinfo, 146 | bool from_last, bool with_default) 147 | { 148 | WindowObject winobj = PG_WINDOW_OBJECT(); 149 | Datum result; 150 | bool isnull; 151 | bool isout; 152 | int runner = 0; 153 | int step = from_last ? -1 : 1; 154 | 155 | for (;;) 156 | { 157 | result = WinGetFuncArgInFrame( 158 | winobj, 0, runner, 159 | from_last ? WINDOW_SEEK_TAIL : WINDOW_SEEK_HEAD, 160 | false, &isnull, &isout); 161 | 162 | if (isout || !isnull) 163 | break; 164 | 165 | runner += step; 166 | } 167 | 168 | if (isout && with_default) 169 | result = WinGetFuncArgCurrent(winobj, 1, &isnull); 170 | 171 | if (isnull) 172 | PG_RETURN_NULL(); 173 | 174 | PG_RETURN_DATUM(result); 175 | } 176 | 177 | /* FIRST_VALUE */ 178 | 179 | Datum 180 | window_first_value_ignore_nulls(PG_FUNCTION_ARGS) 181 | { 182 | return first_last_value_common(fcinfo, false, false); 183 | } 184 | 185 | Datum 186 | window_first_value_ignore_nulls_with_default(PG_FUNCTION_ARGS) 187 | { 188 | return first_last_value_common(fcinfo, false, true); 189 | } 190 | 191 | /* LAST_VALUE */ 192 | 193 | Datum 194 | window_last_value_ignore_nulls(PG_FUNCTION_ARGS) 195 | { 196 | return first_last_value_common(fcinfo, true, false); 197 | } 198 | 199 | Datum 200 | window_last_value_ignore_nulls_with_default(PG_FUNCTION_ARGS) 201 | { 202 | return first_last_value_common(fcinfo, true, true); 203 | } 204 | 205 | /* NTH_VALUE COMMON */ 206 | 207 | static Datum 208 | nth_value_common( 209 | FunctionCallInfo fcinfo, const char *fname, 210 | bool from_last, bool ignore_nulls, bool with_default) 211 | { 212 | WindowObject winobj = PG_WINDOW_OBJECT(); 213 | Datum result; 214 | bool isnull; 215 | bool isout; 216 | int32 nth; 217 | int seektype; 218 | 219 | nth = DatumGetInt32(WinGetFuncArgCurrent(winobj, 1, &isnull)) - 1; 220 | if (isnull) 221 | PG_RETURN_NULL(); 222 | 223 | if (nth < 0) 224 | ereport(ERROR, 225 | (errcode(ERRCODE_INVALID_ARGUMENT_FOR_NTH_VALUE), 226 | errmsg("argument of %s must be greater than zero", fname))); 227 | 228 | if (from_last) 229 | { 230 | seektype = WINDOW_SEEK_TAIL; 231 | nth = -nth; 232 | } 233 | else 234 | seektype = WINDOW_SEEK_HEAD; 235 | 236 | if (ignore_nulls) 237 | { 238 | int runner = 0; 239 | int step = from_last ? -1 : 1; 240 | 241 | for (;;) 242 | { 243 | result = WinGetFuncArgInFrame(winobj, 0, 244 | runner, seektype, false, 245 | &isnull, &isout); 246 | 247 | if (isout) 248 | break; 249 | 250 | if (isnull) 251 | nth += step; 252 | 253 | if (runner == nth) 254 | break; 255 | 256 | runner += step; 257 | } 258 | } 259 | else 260 | { 261 | bool const_offset = get_fn_expr_arg_stable(fcinfo->flinfo, 1); 262 | result = WinGetFuncArgInFrame(winobj, 0, 263 | nth, seektype, const_offset, 264 | &isnull, &isout); 265 | } 266 | 267 | if (isout && with_default) 268 | result = WinGetFuncArgCurrent(winobj, 2, &isnull); 269 | 270 | if (isnull) 271 | PG_RETURN_NULL(); 272 | 273 | PG_RETURN_DATUM(result); 274 | } 275 | 276 | /* NTH_VALUE */ 277 | 278 | Datum 279 | window_nth_value_from_last(PG_FUNCTION_ARGS) 280 | { 281 | return nth_value_common(fcinfo, "nth_value_from_last", true, false, false); 282 | } 283 | 284 | Datum 285 | window_nth_value_from_last_ignore_nulls(PG_FUNCTION_ARGS) 286 | { 287 | return nth_value_common(fcinfo, "nth_value_from_last_ignore_nulls", true, true, false); 288 | } 289 | 290 | Datum 291 | window_nth_value_from_last_ignore_nulls_with_default(PG_FUNCTION_ARGS) 292 | { 293 | return nth_value_common(fcinfo, "nth_value_from_last_ignore_nulls", true, true, true); 294 | } 295 | 296 | Datum 297 | window_nth_value_from_last_with_default(PG_FUNCTION_ARGS) 298 | { 299 | return nth_value_common(fcinfo, "nth_value_from_last", true, false, true); 300 | } 301 | 302 | Datum 303 | window_nth_value_ignore_nulls(PG_FUNCTION_ARGS) 304 | { 305 | return nth_value_common(fcinfo, "nth_value_ignore_nulls", false, true, false); 306 | } 307 | 308 | Datum 309 | window_nth_value_ignore_nulls_with_default(PG_FUNCTION_ARGS) 310 | { 311 | return nth_value_common(fcinfo, "nth_value_ignore_nulls", false, true, true); 312 | } 313 | 314 | Datum 315 | window_nth_value_with_default(PG_FUNCTION_ARGS) 316 | { 317 | return nth_value_common(fcinfo, "nth_value", false, false, true); 318 | } 319 | 320 | /* FLIP_FLOP */ 321 | 322 | static Datum 323 | flip_flop(FunctionCallInfo fcinfo, int flip_argno, int flop_argno) 324 | { 325 | WindowObject winobj = PG_WINDOW_OBJECT(); 326 | flip_flop_context *context; 327 | bool isnull; 328 | 329 | context = (flip_flop_context *) 330 | WinGetPartitionLocalMemory(winobj, sizeof(flip_flop_context)); 331 | 332 | if (!context->flip_flop) 333 | { 334 | bool flip; 335 | 336 | flip = WinGetFuncArgCurrent(winobj, flip_argno, &isnull); 337 | if (!isnull && flip) 338 | { 339 | context->flip_flop = true; 340 | PG_RETURN_BOOL(true); 341 | } 342 | 343 | PG_RETURN_BOOL(false); 344 | } 345 | else 346 | { 347 | bool flop; 348 | 349 | flop = WinGetFuncArgCurrent(winobj, flop_argno, &isnull); 350 | if (!isnull && flop) 351 | context->flip_flop = false; 352 | 353 | PG_RETURN_BOOL(true); 354 | } 355 | } 356 | 357 | Datum 358 | window_flip_flop_1(PG_FUNCTION_ARGS) 359 | { 360 | return flip_flop(fcinfo, 0, 0); 361 | } 362 | 363 | Datum 364 | window_flip_flop_2(PG_FUNCTION_ARGS) 365 | { 366 | return flip_flop(fcinfo, 0, 1); 367 | } 368 | -------------------------------------------------------------------------------- /extra_window_functions.control: -------------------------------------------------------------------------------- 1 | comment = 'Extra window functions for PostgreSQL' 2 | default_version = 1.0 3 | module_pathname = '$libdir/extra_window_functions' 4 | relocatable = true 5 | -------------------------------------------------------------------------------- /open-graph.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/xocolatl/extra_window_functions/0ab6fea1230798a6366f806be052250975e975e4/open-graph.png -------------------------------------------------------------------------------- /sql/regression.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION extra_window_functions; 2 | 3 | CREATE TABLE things ( 4 | part integer NOT NULL, 5 | ord integer NOT NULL, 6 | val integer 7 | ); 8 | 9 | COPY things FROM stdin; 10 | 1 1 64664 11 | 1 2 8779 12 | 1 3 14005 13 | 1 4 57699 14 | 1 5 98842 15 | 1 6 88563 16 | 1 7 70453 17 | 1 8 82824 18 | 1 9 62453 19 | 2 1 \N 20 | 2 2 51714 21 | 2 3 17096 22 | 2 4 41605 23 | 2 5 15366 24 | 2 6 87359 25 | 2 7 98990 26 | 2 8 34982 27 | 2 9 3343 28 | 3 1 21903 29 | 3 2 24605 30 | 3 3 6242 31 | 3 4 24947 32 | 3 5 79535 33 | 3 6 66903 34 | 3 7 42269 35 | 3 8 31143 36 | 3 9 \N 37 | 4 1 \N 38 | 4 2 49723 39 | 4 3 23958 40 | 4 4 80796 41 | 4 5 \N 42 | 4 6 41066 43 | 4 7 72991 44 | 4 8 33734 45 | 4 9 \N 46 | 5 1 \N 47 | 5 2 \N 48 | 5 3 \N 49 | 5 4 \N 50 | 5 5 \N 51 | 5 6 \N 52 | 5 7 \N 53 | 5 8 \N 54 | 5 9 \N 55 | \. 56 | 57 | /* FLIP_FLOP */ 58 | 59 | SELECT part, ord, val, 60 | flip_flop(val % 2 = 0) OVER w AS flip_flop_1, 61 | flip_flop(val % 2 = 0, val % 2 = 1) OVER w AS flip_flop_2 62 | FROM things 63 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 64 | ORDER BY part, ord; 65 | 66 | /* LAG */ 67 | 68 | SELECT part, ord, val, 69 | lag(val) OVER w AS lag, 70 | lag_ignore_nulls(val) OVER w AS lag_in, 71 | lag_ignore_nulls(val, 2) OVER w AS lag_in_off, 72 | lag_ignore_nulls(val, 2, -9999999) OVER w AS lag_in_off_d 73 | FROM things 74 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 75 | ORDER BY part, ord; 76 | 77 | /* LEAD */ 78 | 79 | SELECT part, ord, val, 80 | lead(val) OVER w AS lead, 81 | lead_ignore_nulls(val) OVER w AS lead_in, 82 | lead_ignore_nulls(val, 2) OVER w AS lead_in_off, 83 | lead_ignore_nulls(val, 2, 9999999) OVER w AS lead_in_off_d 84 | FROM things 85 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 86 | ORDER BY part, ord; 87 | 88 | /* FIRST_VALUE */ 89 | 90 | SELECT part, ord, val, 91 | first_value(val) OVER w AS fv, 92 | first_value_ignore_nulls(val) OVER w AS fv_in, 93 | first_value_ignore_nulls(val, 9999999) OVER w AS fv_in_d 94 | FROM things 95 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 96 | ORDER BY part, ord; 97 | 98 | /* LAST_VALUE */ 99 | 100 | SELECT part, ord, val, 101 | last_value(val) OVER w AS lv, 102 | last_value_ignore_nulls(val) OVER w AS lv_in, 103 | last_value_ignore_nulls(val, -9999999) OVER w AS lv_in_d 104 | FROM things 105 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 106 | ORDER BY part, ord; 107 | 108 | /* NTH_VALUE */ 109 | 110 | SELECT part, ord, val, 111 | nth_value(val, 3) OVER w AS nth, 112 | nth_value_ignore_nulls(val, 3) OVER w AS nth_in 113 | FROM things 114 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 115 | ORDER BY part, ord; 116 | 117 | SELECT part, ord, val, 118 | nth_value(val, 3) OVER w AS nth, 119 | nth_value_from_last(val, 3) OVER w AS nth_fl 120 | FROM things 121 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 122 | ORDER BY part, ord; 123 | 124 | SELECT part, ord, val, 125 | nth_value_from_last(val, 3) OVER w AS nth_fl, 126 | nth_value_from_last_ignore_nulls(val, 3) OVER w AS nth_fl_in 127 | FROM things 128 | WINDOW w AS (PARTITION BY part ORDER BY ord ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) 129 | ORDER BY part, ord; 130 | 131 | DROP TABLE things; 132 | 133 | DROP EXTENSION extra_window_functions; 134 | --------------------------------------------------------------------------------