├── .editorconfig ├── .github └── workflows │ └── ci.yml ├── .gitignore ├── LICENSE.md ├── META.json ├── Makefile ├── README.md ├── arraymath--1.0--1.1.sql ├── arraymath--1.0.sql ├── arraymath--1.1.sql ├── arraymath.c ├── arraymath.control ├── ci └── pg_hba.conf ├── expected └── arraymath.out └── sql └── arraymath.sql /.editorconfig: -------------------------------------------------------------------------------- 1 | # http://editorconfig.org 2 | 3 | # top-most EditorConfig file 4 | root = true 5 | 6 | # these are the defaults 7 | [*] 8 | charset = utf-8 9 | end_of_line = lf 10 | insert_final_newline = true 11 | trim_trailing_whitespace = true 12 | 13 | # Test files need kid gloves 14 | [*.{source,out}] 15 | insert_final_newline = true 16 | trim_trailing_whitespace = false 17 | 18 | # C files want tab indentation 19 | [*.{c,h,md}] 20 | indent_style = space 21 | indent_size = 4 22 | 23 | # Makefiles want tab indentation 24 | [Makefile] 25 | indent_style = tab 26 | -------------------------------------------------------------------------------- /.github/workflows/ci.yml: -------------------------------------------------------------------------------- 1 | # GitHub Actions for PostGIS 2 | # 3 | # Paul Ramsey 4 | 5 | name: "CI" 6 | on: [push, pull_request] 7 | 8 | jobs: 9 | linux: 10 | 11 | runs-on: ubuntu-latest 12 | 13 | name: "CI" 14 | strategy: 15 | matrix: 16 | ci: 17 | - { PGVER: 12 } 18 | - { PGVER: 13 } 19 | - { PGVER: 14 } 20 | - { PGVER: 15 } 21 | 22 | steps: 23 | 24 | - name: 'Check Out' 25 | uses: actions/checkout@v3 26 | 27 | - name: 'Install PostgreSQL' 28 | run: | 29 | sudo sh -c 'echo "deb http://apt.postgresql.org/pub/repos/apt $(lsb_release -cs)-pgdg-snapshot main ${{ matrix.ci.PGVER }}" > /etc/apt/sources.list.d/pgdg.list' 30 | curl https://www.postgresql.org/media/keys/ACCC4CF8.asc | gpg --dearmor | sudo tee /etc/apt/trusted.gpg.d/apt.postgresql.org.gpg >/dev/null 31 | sudo apt-get update 32 | sudo apt-get -y install postgresql-${{ matrix.ci.PGVER }} postgresql-server-dev-${{ matrix.ci.PGVER }} 33 | 34 | - name: 'Start PostgreSQL' 35 | run: | 36 | export PGVER=${{ matrix.ci.PGVER }} 37 | export PGDATA=/var/lib/postgresql/$PGVER/main 38 | export PGETC=/etc/postgresql/$PGVER/main 39 | export PGBIN=/usr/lib/postgresql/$PGVER/bin 40 | sudo cp ./ci/pg_hba.conf $PGETC/pg_hba.conf 41 | sudo su postgres -c "$PGBIN/pg_ctl --pgdata $PGDATA start -o '-c config_file=$PGETC/postgresql.conf -p 5432'" 42 | 43 | - name: 'Build & Test' 44 | run: | 45 | export PGVER=${{ matrix.ci.PGVER }} 46 | export PGBIN=/usr/lib/postgresql/$PGVER/bin 47 | export PATH=$PGBIN:$PATH 48 | export PG_CONFIG=$PGBIN/pg_config 49 | export PG_CFLAGS=-Werror 50 | make 51 | sudo -E make PG_CONFIG=$PG_CONFIG install 52 | PGUSER=postgres make installcheck || (cat regression.diffs && /bin/false) 53 | 54 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | *.o 2 | *.a 3 | *.dll 4 | *.so 5 | *.so.* 6 | *.dylib 7 | regression.diffs 8 | regression.out 9 | results/arraymath.out 10 | -------------------------------------------------------------------------------- /LICENSE.md: -------------------------------------------------------------------------------- 1 | Copyright (C) 2012 Paul Ramsey 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions: 4 | 5 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. 6 | 7 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 8 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "arraymath", 3 | "abstract": "Element-by-element math operations for array types", 4 | "description": "Array math allows you to do math and logic with arrays element-by-element. So you can add two arrays, or an array and a value, or compare the elements of two arrays.", 5 | "version": "1.0.0", 6 | "maintainer": [ 7 | "Paul Ramsey " 8 | ], 9 | "license": { 10 | "mit": "http://en.wikipedia.org/wiki/MIT_License" 11 | }, 12 | "prereqs": { 13 | "runtime": { 14 | "requires": { 15 | "PostgreSQL": "9.1.0" 16 | }, 17 | "recommends": { 18 | "PostgreSQL": "9.1.3" 19 | } 20 | } 21 | }, 22 | "provides": { 23 | "arraymath": { 24 | "file": "arraymath--1.0.sql", 25 | "docfile": "README.md", 26 | "version": "1.0.0", 27 | "abstract": "Array math operations for PostgreSQL" 28 | } 29 | }, 30 | "resources": { 31 | "homepage": "https://github.com/pramsey/pgsql-arraymath/", 32 | "bugtracker": { 33 | "web": "https://github.com/pramsey/pgsql-arraymath/issues" 34 | }, 35 | "repository": { 36 | "url": "https://github.com/pramsey/pgsql-arraymath.git", 37 | "web": "https://github.com/pramsey/pgsql-arraymath/", 38 | "type": "git" 39 | } 40 | }, 41 | "generated_by": "Paul Ramsey", 42 | "meta-spec": { 43 | "version": "1.0.0", 44 | "url": "http://pgxn.org/meta/spec.txt" 45 | }, 46 | "tags": [ 47 | "array", 48 | "elements", 49 | "operators" 50 | ] 51 | } 52 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | 2 | MODULE_big = arraymath 3 | OBJS = arraymath.o 4 | EXTENSION = arraymath 5 | REGRESS = arraymath 6 | EXTRA_CLEAN = 7 | 8 | DATA = \ 9 | arraymath--1.0.sql \ 10 | arraymath--1.1.sql \ 11 | arraymath--1.0--1.1.sql 12 | 13 | PG_CONFIG = pg_config 14 | 15 | PGXS := $(shell $(PG_CONFIG) --pgxs) 16 | include $(PGXS) 17 | 18 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | [![Build Status](https://github.com/pramsey/pgsql-arraymath/actions/workflows/ci.yml/badge.svg)](https://github.com/pramsey/pgsql-arraymath/actions/workflows/ci.yml) 2 | 3 | # pgsql-arraymath 4 | 5 | An extension for element-by-element operations on PostgreSQL arrays with a integer, float or numeric data type. 6 | 7 | ## Enabling in a database 8 | 9 | ```sql 10 | CREATE EXTENSION arraymath; 11 | ``` 12 | 13 | The operators are all the usual ones, but prefixed by ``@`` to indicate their element-by-element nature. 14 | 15 | * `@=` element-by-element equality, returns boolean[] 16 | * `@<` element-by-element less than, returns boolean[] 17 | * `@>` element-by-element greater than, returns boolean[] 18 | * `@<=` element-by-element less than or equals, returns boolean[] 19 | * `@>=` element-by-element greater than or equals, returns boolean[] 20 | * `@+` element-by-element addition 21 | * `@-` element-by-element subtraction 22 | * `@*` element-by-element multiplication 23 | * `@/` element-by-element division 24 | 25 | The functions are prefixed by `array_`. 26 | 27 | * `array_sum(anyarray)` sums up all the elements 28 | * `array_avg(anyarray)` returns float average of all elements 29 | * `array_min(anyarray)` returns minimum of all elements 30 | * `array_max(anyarray)` returns maximum of all elements 31 | * `array_median(anyarray)` returns the median of all elements 32 | * `array_sort(anyarray)` sorts the array from smallest to largest 33 | * `array_rsort(anyarray)` sorts the array from largest to smallest 34 | 35 | 36 | ## Array versus Constant 37 | 38 | If you apply the operators with an array on one side and a constant on the other, the constant will be applied to all the elements of the array. For example: 39 | 40 | ```sql 41 | SELECT ARRAY[1,2,3,4] @< 4; 42 | ``` 43 | ``` 44 | {t,t,t,f} 45 | ``` 46 | ```sql 47 | SELECT ARRAY[3.4,5.6,7.6] @* 8.1; 48 | ``` 49 | ``` 50 | {27.54,45.36,61.56} 51 | ``` 52 | 53 | ## Array versus Array 54 | 55 | If you apply the operators with an array on both sides, the operator will be applied to each element pairing in turn, returning an array as long as the larger of the two inputs. Where the shorter array runs out of elements, the process will simply move back to the start of the array. For example: 56 | 57 | ``` 58 | SELECT ARRAY[1,2] @+ ARRAY[3,4]; 59 | 60 | {4,6} 61 | 62 | SELECT ARRAY[1,2,3,4,5,6] @* ARRAY[1,2]; 63 | 64 | {1,4,3,8,5,12} 65 | 66 | SELECT ARRAY[1,1,1,1] @< ARRAY[0,2]; 67 | 68 | {f,t,f,t} 69 | 70 | SELECT ARRAY[1,2,3] @= ARRAY[3,2,1]; 71 | 72 | {f,t,f} 73 | ``` 74 | 75 | ## Array Functions 76 | 77 | The extension includes a few utility functions that work to summarize or manipulate an array directly without unnesting. 78 | 79 | ``` 80 | SELECT array_sort(ARRAY[9,1,8,2,7,3,6,4,5]); 81 | 82 | {1,2,3,4,5,6,7,8,9} 83 | 84 | SELECT array_sort(ARRAY[9,1,8,2,7,3,6,4,5], reverse => true); 85 | 86 | {9,8,7,6,5,4,3,2,1} 87 | 88 | SELECT array_sum(ARRAY[1,2,3,4,5,6,7,8,9]); 89 | 90 | 45 91 | 92 | SELECT array_avg(ARRAY[1,2,3,4,5,6,7,8,9]); 93 | 94 | 5 95 | 96 | SELECT array_min(ARRAY[1,2,3,4,5,6,7,8,9]); 97 | 98 | 1 99 | 100 | SELECT array_max(ARRAY[1,2,3,4,5,6,7,8,9]); 101 | 102 | 9 103 | 104 | SELECT array_median(ARRAY[1,2,3,4,5,6,7,8,9]); 105 | 106 | 5 107 | ``` 108 | 109 | As far as possible, the functions preserve the data type of the original input. For the median and mean, the return type is `float8`. 110 | 111 | ``` 112 | SELECT pg_typeof(array_min(ARRAY[1,2,3,4,5,6,7,8,9])); 113 | 114 | integer 115 | ``` 116 | 117 | -------------------------------------------------------------------------------- /arraymath--1.0--1.1.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION array_sum(arr anyarray) 2 | RETURNS ANYELEMENT 3 | AS 'MODULE_PATHNAME' 4 | LANGUAGE 'c' 5 | IMMUTABLE STRICT; 6 | 7 | CREATE OR REPLACE FUNCTION array_avg(arr anyarray) 8 | RETURNS float8 9 | AS 'MODULE_PATHNAME' 10 | LANGUAGE 'c' 11 | IMMUTABLE STRICT; 12 | 13 | CREATE OR REPLACE FUNCTION array_median(arr anyarray) 14 | RETURNS float8 15 | AS 'MODULE_PATHNAME' 16 | LANGUAGE 'c' 17 | IMMUTABLE STRICT; 18 | 19 | CREATE OR REPLACE FUNCTION array_min(arr anyarray) 20 | RETURNS ANYELEMENT 21 | AS 'MODULE_PATHNAME' 22 | LANGUAGE 'c' 23 | IMMUTABLE STRICT; 24 | 25 | CREATE OR REPLACE FUNCTION array_max(arr anyarray) 26 | RETURNS ANYELEMENT 27 | AS 'MODULE_PATHNAME' 28 | LANGUAGE 'c' 29 | IMMUTABLE STRICT; 30 | 31 | CREATE OR REPLACE FUNCTION array_sort(arr anyarray, reverse boolean DEFAULT false) 32 | RETURNS ANYARRAY 33 | AS 'MODULE_PATHNAME' 34 | LANGUAGE 'c' 35 | IMMUTABLE STRICT; 36 | -------------------------------------------------------------------------------- /arraymath--1.0.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION arraymath" to load this file. \quit 3 | 4 | CREATE OR REPLACE FUNCTION array_compare_value(arr1 ANYARRAY, elt2 ANYELEMENT, op TEXT) 5 | RETURNS boolean[] 6 | AS 'MODULE_PATHNAME' 7 | LANGUAGE 'c' 8 | IMMUTABLE STRICT; 9 | 10 | CREATE OR REPLACE FUNCTION array_equals_value(arr1 ANYARRAY, elt2 ANYELEMENT) 11 | RETURNS boolean[] 12 | AS 'SELECT array_compare_value($1,$2,''='')' 13 | LANGUAGE 'sql' 14 | IMMUTABLE STRICT; 15 | 16 | CREATE OR REPLACE FUNCTION array_gt_value(arr1 ANYARRAY, elt2 ANYELEMENT) 17 | RETURNS boolean[] 18 | AS 'SELECT array_compare_value($1,$2,''>'')' 19 | LANGUAGE 'sql' 20 | IMMUTABLE STRICT; 21 | 22 | CREATE OR REPLACE FUNCTION array_lt_value(arr1 ANYARRAY, elt2 ANYELEMENT) 23 | RETURNS boolean[] 24 | AS 'SELECT array_compare_value($1,$2,''<'')' 25 | LANGUAGE 'sql' 26 | IMMUTABLE STRICT; 27 | 28 | CREATE OR REPLACE FUNCTION array_gte_value(arr1 ANYARRAY, elt2 ANYELEMENT) 29 | RETURNS boolean[] 30 | AS 'SELECT array_compare_value($1,$2,''>='')' 31 | LANGUAGE 'sql' 32 | IMMUTABLE STRICT; 33 | 34 | CREATE OR REPLACE FUNCTION array_lte_value(arr1 ANYARRAY, elt2 ANYELEMENT) 35 | RETURNS boolean[] 36 | AS 'SELECT array_compare_value($1,$2,''<='')' 37 | LANGUAGE 'sql' 38 | IMMUTABLE STRICT; 39 | 40 | 41 | CREATE OR REPLACE FUNCTION value_equals_array(elt2 ANYELEMENT, arr1 ANYARRAY) 42 | RETURNS boolean[] 43 | AS 'SELECT array_compare_value($2,$1,''='')' 44 | LANGUAGE 'sql' 45 | IMMUTABLE STRICT; 46 | 47 | CREATE OR REPLACE FUNCTION value_gt_array(elt2 ANYELEMENT, arr1 ANYARRAY) 48 | RETURNS boolean[] 49 | AS 'SELECT array_compare_value($2,$1,''>'')' 50 | LANGUAGE 'sql' 51 | IMMUTABLE STRICT; 52 | 53 | CREATE OR REPLACE FUNCTION value_lt_array(elt2 ANYELEMENT, arr1 ANYARRAY) 54 | RETURNS boolean[] 55 | AS 'SELECT array_compare_value($2,$1,''<'')' 56 | LANGUAGE 'sql' 57 | IMMUTABLE STRICT; 58 | 59 | CREATE OR REPLACE FUNCTION value_gte_array(elt2 ANYELEMENT, arr1 ANYARRAY) 60 | RETURNS boolean[] 61 | AS 'SELECT array_compare_value($2,$1,''>='')' 62 | LANGUAGE 'sql' 63 | IMMUTABLE STRICT; 64 | 65 | CREATE OR REPLACE FUNCTION value_lte_array(elt2 ANYELEMENT, arr1 ANYARRAY) 66 | RETURNS boolean[] 67 | AS 'SELECT array_compare_value($2,$1,''<='')' 68 | LANGUAGE 'sql' 69 | IMMUTABLE STRICT; 70 | 71 | 72 | 73 | CREATE OPERATOR @= ( 74 | LEFTARG = anyarray, 75 | RIGHTARG = anyelement, 76 | PROCEDURE = array_equals_value 77 | ); 78 | 79 | CREATE OPERATOR @< ( 80 | LEFTARG = anyarray, 81 | RIGHTARG = anyelement, 82 | PROCEDURE = array_lt_value 83 | ); 84 | 85 | CREATE OPERATOR @<= ( 86 | LEFTARG = anyarray, 87 | RIGHTARG = anyelement, 88 | PROCEDURE = array_lte_value 89 | ); 90 | 91 | CREATE OPERATOR @> ( 92 | LEFTARG = anyarray, 93 | RIGHTARG = anyelement, 94 | PROCEDURE = array_gt_value 95 | ); 96 | 97 | CREATE OPERATOR @>= ( 98 | LEFTARG = anyarray, 99 | RIGHTARG = anyelement, 100 | PROCEDURE = array_gte_value 101 | ); 102 | 103 | 104 | 105 | CREATE OPERATOR @= ( 106 | LEFTARG = anyelement, 107 | RIGHTARG = anyarray, 108 | PROCEDURE = value_equals_array 109 | ); 110 | 111 | CREATE OPERATOR @< ( 112 | LEFTARG = anyelement, 113 | RIGHTARG = anyarray, 114 | PROCEDURE = value_lt_array 115 | ); 116 | 117 | CREATE OPERATOR @<= ( 118 | LEFTARG = anyelement, 119 | RIGHTARG = anyarray, 120 | PROCEDURE = value_lte_array 121 | ); 122 | 123 | CREATE OPERATOR @> ( 124 | LEFTARG = anyelement, 125 | RIGHTARG = anyarray, 126 | PROCEDURE = value_gt_array 127 | ); 128 | 129 | CREATE OPERATOR @>= ( 130 | LEFTARG = anyelement, 131 | RIGHTARG = anyarray, 132 | PROCEDURE = value_gte_array 133 | ); 134 | 135 | 136 | 137 | 138 | CREATE OR REPLACE FUNCTION array_math_value(arr1 ANYARRAY, elt2 ANYELEMENT, op TEXT) 139 | RETURNS anyarray 140 | AS 'MODULE_PATHNAME' 141 | LANGUAGE 'c' 142 | IMMUTABLE STRICT; 143 | 144 | 145 | 146 | CREATE OR REPLACE FUNCTION array_plus_value(arr1 ANYARRAY, elt2 ANYELEMENT) 147 | RETURNS anyarray 148 | AS 'SELECT array_math_value($1,$2,''+'')' 149 | LANGUAGE 'sql' 150 | IMMUTABLE STRICT; 151 | 152 | CREATE OR REPLACE FUNCTION value_plus_array(elt2 ANYELEMENT, arr1 ANYARRAY) 153 | RETURNS anyarray 154 | AS 'SELECT array_math_value($2,$1,''+'')' 155 | LANGUAGE 'sql' 156 | IMMUTABLE STRICT; 157 | 158 | CREATE OPERATOR @+ ( 159 | LEFTARG = anyarray, 160 | RIGHTARG = anyelement, 161 | PROCEDURE = array_plus_value 162 | ); 163 | 164 | CREATE OPERATOR @+ ( 165 | LEFTARG = anyelement, 166 | RIGHTARG = anyarray, 167 | PROCEDURE = value_plus_array 168 | ); 169 | 170 | 171 | CREATE OR REPLACE FUNCTION array_minus_value(arr1 ANYARRAY, elt2 ANYELEMENT) 172 | RETURNS anyarray 173 | AS 'SELECT array_math_value($1,$2,''-'')' 174 | LANGUAGE 'sql' 175 | IMMUTABLE STRICT; 176 | 177 | CREATE OR REPLACE FUNCTION value_minus_array(elt2 ANYELEMENT, arr1 ANYARRAY) 178 | RETURNS anyarray 179 | AS 'SELECT array_math_value($2,$1,''-'')' 180 | LANGUAGE 'sql' 181 | IMMUTABLE STRICT; 182 | 183 | CREATE OPERATOR @- ( 184 | LEFTARG = anyarray, 185 | RIGHTARG = anyelement, 186 | PROCEDURE = array_minus_value 187 | ); 188 | 189 | CREATE OPERATOR @- ( 190 | LEFTARG = anyelement, 191 | RIGHTARG = anyarray, 192 | PROCEDURE = value_minus_array 193 | ); 194 | 195 | 196 | CREATE OR REPLACE FUNCTION array_times_value(arr1 ANYARRAY, elt2 ANYELEMENT) 197 | RETURNS anyarray 198 | AS 'SELECT array_math_value($1,$2,''*'')' 199 | LANGUAGE 'sql' 200 | IMMUTABLE STRICT; 201 | 202 | CREATE OR REPLACE FUNCTION value_times_array(elt2 ANYELEMENT, arr1 ANYARRAY) 203 | RETURNS anyarray 204 | AS 'SELECT array_math_value($2,$1,''*'')' 205 | LANGUAGE 'sql' 206 | IMMUTABLE STRICT; 207 | 208 | CREATE OPERATOR @* ( 209 | LEFTARG = anyarray, 210 | RIGHTARG = anyelement, 211 | PROCEDURE = array_times_value 212 | ); 213 | 214 | CREATE OPERATOR @* ( 215 | LEFTARG = anyelement, 216 | RIGHTARG = anyarray, 217 | PROCEDURE = value_times_array 218 | ); 219 | 220 | 221 | CREATE OR REPLACE FUNCTION array_div_value(arr1 ANYARRAY, elt2 ANYELEMENT) 222 | RETURNS anyarray 223 | AS 'SELECT array_math_value($1,$2,''/'')' 224 | LANGUAGE 'sql' 225 | IMMUTABLE STRICT; 226 | 227 | CREATE OR REPLACE FUNCTION value_div_array(elt2 ANYELEMENT, arr1 ANYARRAY) 228 | RETURNS anyarray 229 | AS 'SELECT array_math_value($2,$1,''/'')' 230 | LANGUAGE 'sql' 231 | IMMUTABLE STRICT; 232 | 233 | CREATE OPERATOR @/ ( 234 | LEFTARG = anyarray, 235 | RIGHTARG = anyelement, 236 | PROCEDURE = array_div_value 237 | ); 238 | 239 | CREATE OPERATOR @/ ( 240 | LEFTARG = anyelement, 241 | RIGHTARG = anyarray, 242 | PROCEDURE = value_div_array 243 | ); 244 | 245 | 246 | 247 | CREATE OR REPLACE FUNCTION array_compare_array(arr1 ANYARRAY, arr2 ANYARRAY, op TEXT) 248 | RETURNS boolean[] 249 | AS 'MODULE_PATHNAME' 250 | LANGUAGE 'c' 251 | IMMUTABLE STRICT; 252 | 253 | CREATE OR REPLACE FUNCTION array_equals_array(arr1 ANYARRAY, arr2 ANYARRAY) 254 | RETURNS boolean[] 255 | AS 'SELECT array_compare_array($1,$2,''='')' 256 | LANGUAGE 'sql' 257 | IMMUTABLE STRICT; 258 | 259 | CREATE OPERATOR @= ( 260 | LEFTARG = anyarray, 261 | RIGHTARG = anyarray, 262 | PROCEDURE = array_equals_array 263 | ); 264 | 265 | CREATE OR REPLACE FUNCTION array_lt_array(arr1 ANYARRAY, arr2 ANYARRAY) 266 | RETURNS boolean[] 267 | AS 'SELECT array_compare_array($1,$2,''<'')' 268 | LANGUAGE 'sql' 269 | IMMUTABLE STRICT; 270 | 271 | CREATE OPERATOR @< ( 272 | LEFTARG = anyarray, 273 | RIGHTARG = anyarray, 274 | PROCEDURE = array_lt_array 275 | ); 276 | 277 | CREATE OR REPLACE FUNCTION array_gt_array(arr1 ANYARRAY, arr2 ANYARRAY) 278 | RETURNS boolean[] 279 | AS 'SELECT array_compare_array($1,$2,''>'')' 280 | LANGUAGE 'sql' 281 | IMMUTABLE STRICT; 282 | 283 | CREATE OPERATOR @> ( 284 | LEFTARG = anyarray, 285 | RIGHTARG = anyarray, 286 | PROCEDURE = array_gt_array 287 | ); 288 | 289 | CREATE OR REPLACE FUNCTION array_lte_array(arr1 ANYARRAY, arr2 ANYARRAY) 290 | RETURNS boolean[] 291 | AS 'SELECT array_compare_array($1,$2,''<='')' 292 | LANGUAGE 'sql' 293 | IMMUTABLE STRICT; 294 | 295 | CREATE OPERATOR @<= ( 296 | LEFTARG = anyarray, 297 | RIGHTARG = anyarray, 298 | PROCEDURE = array_lte_array 299 | ); 300 | 301 | CREATE OR REPLACE FUNCTION array_gte_array(arr1 ANYARRAY, arr2 ANYARRAY) 302 | RETURNS boolean[] 303 | AS 'SELECT array_compare_array($1,$2,''>='')' 304 | LANGUAGE 'sql' 305 | IMMUTABLE STRICT; 306 | 307 | CREATE OPERATOR @>= ( 308 | LEFTARG = anyarray, 309 | RIGHTARG = anyarray, 310 | PROCEDURE = array_gte_array 311 | ); 312 | 313 | 314 | CREATE OR REPLACE FUNCTION array_math_array(arr1 ANYARRAY, arr2 ANYARRAY, op TEXT) 315 | RETURNS anyarray 316 | AS 'MODULE_PATHNAME' 317 | LANGUAGE 'c' 318 | IMMUTABLE STRICT; 319 | 320 | CREATE OR REPLACE FUNCTION array_plus_array(arr1 ANYARRAY, arr2 ANYARRAY) 321 | RETURNS anyarray 322 | AS 'SELECT array_math_array($1,$2,''+'')' 323 | LANGUAGE 'sql' 324 | IMMUTABLE STRICT; 325 | 326 | CREATE OPERATOR @+ ( 327 | LEFTARG = anyarray, 328 | RIGHTARG = anyarray, 329 | PROCEDURE = array_plus_array 330 | ); 331 | 332 | CREATE OR REPLACE FUNCTION array_minus_array(arr1 ANYARRAY, arr2 ANYARRAY) 333 | RETURNS anyarray 334 | AS 'SELECT array_math_array($1,$2,''-'')' 335 | LANGUAGE 'sql' 336 | IMMUTABLE STRICT; 337 | 338 | CREATE OPERATOR @- ( 339 | LEFTARG = anyarray, 340 | RIGHTARG = anyarray, 341 | PROCEDURE = array_minus_array 342 | ); 343 | 344 | CREATE OR REPLACE FUNCTION array_times_array(arr1 ANYARRAY, arr2 ANYARRAY) 345 | RETURNS anyarray 346 | AS 'SELECT array_math_array($1,$2,''*'')' 347 | LANGUAGE 'sql' 348 | IMMUTABLE STRICT; 349 | 350 | CREATE OPERATOR @* ( 351 | LEFTARG = anyarray, 352 | RIGHTARG = anyarray, 353 | PROCEDURE = array_times_array 354 | ); 355 | 356 | CREATE OR REPLACE FUNCTION array_div_array(arr1 ANYARRAY, arr2 ANYARRAY) 357 | RETURNS anyarray 358 | AS 'SELECT array_math_array($1,$2,''/'')' 359 | LANGUAGE 'sql' 360 | IMMUTABLE STRICT; 361 | 362 | CREATE OPERATOR @/ ( 363 | LEFTARG = anyarray, 364 | RIGHTARG = anyarray, 365 | PROCEDURE = array_div_array 366 | ); 367 | 368 | -------------------------------------------------------------------------------- /arraymath--1.1.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION arraymath" to load this file. \quit 3 | 4 | CREATE OR REPLACE FUNCTION array_compare_value(arr1 ANYARRAY, elt2 ANYELEMENT, op TEXT) 5 | RETURNS boolean[] 6 | AS 'MODULE_PATHNAME' 7 | LANGUAGE 'c' 8 | IMMUTABLE STRICT; 9 | 10 | CREATE OR REPLACE FUNCTION array_equals_value(arr1 ANYARRAY, elt2 ANYELEMENT) 11 | RETURNS boolean[] 12 | AS 'SELECT array_compare_value($1,$2,''='')' 13 | LANGUAGE 'sql' 14 | IMMUTABLE STRICT; 15 | 16 | CREATE OR REPLACE FUNCTION array_gt_value(arr1 ANYARRAY, elt2 ANYELEMENT) 17 | RETURNS boolean[] 18 | AS 'SELECT array_compare_value($1,$2,''>'')' 19 | LANGUAGE 'sql' 20 | IMMUTABLE STRICT; 21 | 22 | CREATE OR REPLACE FUNCTION array_lt_value(arr1 ANYARRAY, elt2 ANYELEMENT) 23 | RETURNS boolean[] 24 | AS 'SELECT array_compare_value($1,$2,''<'')' 25 | LANGUAGE 'sql' 26 | IMMUTABLE STRICT; 27 | 28 | CREATE OR REPLACE FUNCTION array_gte_value(arr1 ANYARRAY, elt2 ANYELEMENT) 29 | RETURNS boolean[] 30 | AS 'SELECT array_compare_value($1,$2,''>='')' 31 | LANGUAGE 'sql' 32 | IMMUTABLE STRICT; 33 | 34 | CREATE OR REPLACE FUNCTION array_lte_value(arr1 ANYARRAY, elt2 ANYELEMENT) 35 | RETURNS boolean[] 36 | AS 'SELECT array_compare_value($1,$2,''<='')' 37 | LANGUAGE 'sql' 38 | IMMUTABLE STRICT; 39 | 40 | 41 | CREATE OR REPLACE FUNCTION value_equals_array(elt2 ANYELEMENT, arr1 ANYARRAY) 42 | RETURNS boolean[] 43 | AS 'SELECT array_compare_value($2,$1,''='')' 44 | LANGUAGE 'sql' 45 | IMMUTABLE STRICT; 46 | 47 | CREATE OR REPLACE FUNCTION value_gt_array(elt2 ANYELEMENT, arr1 ANYARRAY) 48 | RETURNS boolean[] 49 | AS 'SELECT array_compare_value($2,$1,''>'')' 50 | LANGUAGE 'sql' 51 | IMMUTABLE STRICT; 52 | 53 | CREATE OR REPLACE FUNCTION value_lt_array(elt2 ANYELEMENT, arr1 ANYARRAY) 54 | RETURNS boolean[] 55 | AS 'SELECT array_compare_value($2,$1,''<'')' 56 | LANGUAGE 'sql' 57 | IMMUTABLE STRICT; 58 | 59 | CREATE OR REPLACE FUNCTION value_gte_array(elt2 ANYELEMENT, arr1 ANYARRAY) 60 | RETURNS boolean[] 61 | AS 'SELECT array_compare_value($2,$1,''>='')' 62 | LANGUAGE 'sql' 63 | IMMUTABLE STRICT; 64 | 65 | CREATE OR REPLACE FUNCTION value_lte_array(elt2 ANYELEMENT, arr1 ANYARRAY) 66 | RETURNS boolean[] 67 | AS 'SELECT array_compare_value($2,$1,''<='')' 68 | LANGUAGE 'sql' 69 | IMMUTABLE STRICT; 70 | 71 | 72 | 73 | CREATE OPERATOR @= ( 74 | LEFTARG = anyarray, 75 | RIGHTARG = anyelement, 76 | PROCEDURE = array_equals_value 77 | ); 78 | 79 | CREATE OPERATOR @< ( 80 | LEFTARG = anyarray, 81 | RIGHTARG = anyelement, 82 | PROCEDURE = array_lt_value 83 | ); 84 | 85 | CREATE OPERATOR @<= ( 86 | LEFTARG = anyarray, 87 | RIGHTARG = anyelement, 88 | PROCEDURE = array_lte_value 89 | ); 90 | 91 | CREATE OPERATOR @> ( 92 | LEFTARG = anyarray, 93 | RIGHTARG = anyelement, 94 | PROCEDURE = array_gt_value 95 | ); 96 | 97 | CREATE OPERATOR @>= ( 98 | LEFTARG = anyarray, 99 | RIGHTARG = anyelement, 100 | PROCEDURE = array_gte_value 101 | ); 102 | 103 | 104 | 105 | CREATE OPERATOR @= ( 106 | LEFTARG = anyelement, 107 | RIGHTARG = anyarray, 108 | PROCEDURE = value_equals_array 109 | ); 110 | 111 | CREATE OPERATOR @< ( 112 | LEFTARG = anyelement, 113 | RIGHTARG = anyarray, 114 | PROCEDURE = value_lt_array 115 | ); 116 | 117 | CREATE OPERATOR @<= ( 118 | LEFTARG = anyelement, 119 | RIGHTARG = anyarray, 120 | PROCEDURE = value_lte_array 121 | ); 122 | 123 | CREATE OPERATOR @> ( 124 | LEFTARG = anyelement, 125 | RIGHTARG = anyarray, 126 | PROCEDURE = value_gt_array 127 | ); 128 | 129 | CREATE OPERATOR @>= ( 130 | LEFTARG = anyelement, 131 | RIGHTARG = anyarray, 132 | PROCEDURE = value_gte_array 133 | ); 134 | 135 | 136 | 137 | 138 | CREATE OR REPLACE FUNCTION array_math_value(arr1 ANYARRAY, elt2 ANYELEMENT, op TEXT) 139 | RETURNS anyarray 140 | AS 'MODULE_PATHNAME' 141 | LANGUAGE 'c' 142 | IMMUTABLE STRICT; 143 | 144 | 145 | 146 | CREATE OR REPLACE FUNCTION array_plus_value(arr1 ANYARRAY, elt2 ANYELEMENT) 147 | RETURNS anyarray 148 | AS 'SELECT array_math_value($1,$2,''+'')' 149 | LANGUAGE 'sql' 150 | IMMUTABLE STRICT; 151 | 152 | CREATE OR REPLACE FUNCTION value_plus_array(elt2 ANYELEMENT, arr1 ANYARRAY) 153 | RETURNS anyarray 154 | AS 'SELECT array_math_value($2,$1,''+'')' 155 | LANGUAGE 'sql' 156 | IMMUTABLE STRICT; 157 | 158 | CREATE OPERATOR @+ ( 159 | LEFTARG = anyarray, 160 | RIGHTARG = anyelement, 161 | PROCEDURE = array_plus_value 162 | ); 163 | 164 | CREATE OPERATOR @+ ( 165 | LEFTARG = anyelement, 166 | RIGHTARG = anyarray, 167 | PROCEDURE = value_plus_array 168 | ); 169 | 170 | 171 | CREATE OR REPLACE FUNCTION array_minus_value(arr1 ANYARRAY, elt2 ANYELEMENT) 172 | RETURNS anyarray 173 | AS 'SELECT array_math_value($1,$2,''-'')' 174 | LANGUAGE 'sql' 175 | IMMUTABLE STRICT; 176 | 177 | CREATE OR REPLACE FUNCTION value_minus_array(elt2 ANYELEMENT, arr1 ANYARRAY) 178 | RETURNS anyarray 179 | AS 'SELECT array_math_value($2,$1,''-'')' 180 | LANGUAGE 'sql' 181 | IMMUTABLE STRICT; 182 | 183 | CREATE OPERATOR @- ( 184 | LEFTARG = anyarray, 185 | RIGHTARG = anyelement, 186 | PROCEDURE = array_minus_value 187 | ); 188 | 189 | CREATE OPERATOR @- ( 190 | LEFTARG = anyelement, 191 | RIGHTARG = anyarray, 192 | PROCEDURE = value_minus_array 193 | ); 194 | 195 | 196 | CREATE OR REPLACE FUNCTION array_times_value(arr1 ANYARRAY, elt2 ANYELEMENT) 197 | RETURNS anyarray 198 | AS 'SELECT array_math_value($1,$2,''*'')' 199 | LANGUAGE 'sql' 200 | IMMUTABLE STRICT; 201 | 202 | CREATE OR REPLACE FUNCTION value_times_array(elt2 ANYELEMENT, arr1 ANYARRAY) 203 | RETURNS anyarray 204 | AS 'SELECT array_math_value($2,$1,''*'')' 205 | LANGUAGE 'sql' 206 | IMMUTABLE STRICT; 207 | 208 | CREATE OPERATOR @* ( 209 | LEFTARG = anyarray, 210 | RIGHTARG = anyelement, 211 | PROCEDURE = array_times_value 212 | ); 213 | 214 | CREATE OPERATOR @* ( 215 | LEFTARG = anyelement, 216 | RIGHTARG = anyarray, 217 | PROCEDURE = value_times_array 218 | ); 219 | 220 | 221 | CREATE OR REPLACE FUNCTION array_div_value(arr1 ANYARRAY, elt2 ANYELEMENT) 222 | RETURNS anyarray 223 | AS 'SELECT array_math_value($1,$2,''/'')' 224 | LANGUAGE 'sql' 225 | IMMUTABLE STRICT; 226 | 227 | CREATE OR REPLACE FUNCTION value_div_array(elt2 ANYELEMENT, arr1 ANYARRAY) 228 | RETURNS anyarray 229 | AS 'SELECT array_math_value($2,$1,''/'')' 230 | LANGUAGE 'sql' 231 | IMMUTABLE STRICT; 232 | 233 | CREATE OPERATOR @/ ( 234 | LEFTARG = anyarray, 235 | RIGHTARG = anyelement, 236 | PROCEDURE = array_div_value 237 | ); 238 | 239 | CREATE OPERATOR @/ ( 240 | LEFTARG = anyelement, 241 | RIGHTARG = anyarray, 242 | PROCEDURE = value_div_array 243 | ); 244 | 245 | 246 | 247 | CREATE OR REPLACE FUNCTION array_compare_array(arr1 ANYARRAY, arr2 ANYARRAY, op TEXT) 248 | RETURNS boolean[] 249 | AS 'MODULE_PATHNAME' 250 | LANGUAGE 'c' 251 | IMMUTABLE STRICT; 252 | 253 | CREATE OR REPLACE FUNCTION array_equals_array(arr1 ANYARRAY, arr2 ANYARRAY) 254 | RETURNS boolean[] 255 | AS 'SELECT array_compare_array($1,$2,''='')' 256 | LANGUAGE 'sql' 257 | IMMUTABLE STRICT; 258 | 259 | CREATE OPERATOR @= ( 260 | LEFTARG = anyarray, 261 | RIGHTARG = anyarray, 262 | PROCEDURE = array_equals_array 263 | ); 264 | 265 | CREATE OR REPLACE FUNCTION array_lt_array(arr1 ANYARRAY, arr2 ANYARRAY) 266 | RETURNS boolean[] 267 | AS 'SELECT array_compare_array($1,$2,''<'')' 268 | LANGUAGE 'sql' 269 | IMMUTABLE STRICT; 270 | 271 | CREATE OPERATOR @< ( 272 | LEFTARG = anyarray, 273 | RIGHTARG = anyarray, 274 | PROCEDURE = array_lt_array 275 | ); 276 | 277 | CREATE OR REPLACE FUNCTION array_gt_array(arr1 ANYARRAY, arr2 ANYARRAY) 278 | RETURNS boolean[] 279 | AS 'SELECT array_compare_array($1,$2,''>'')' 280 | LANGUAGE 'sql' 281 | IMMUTABLE STRICT; 282 | 283 | CREATE OPERATOR @> ( 284 | LEFTARG = anyarray, 285 | RIGHTARG = anyarray, 286 | PROCEDURE = array_gt_array 287 | ); 288 | 289 | CREATE OR REPLACE FUNCTION array_lte_array(arr1 ANYARRAY, arr2 ANYARRAY) 290 | RETURNS boolean[] 291 | AS 'SELECT array_compare_array($1,$2,''<='')' 292 | LANGUAGE 'sql' 293 | IMMUTABLE STRICT; 294 | 295 | CREATE OPERATOR @<= ( 296 | LEFTARG = anyarray, 297 | RIGHTARG = anyarray, 298 | PROCEDURE = array_lte_array 299 | ); 300 | 301 | CREATE OR REPLACE FUNCTION array_gte_array(arr1 ANYARRAY, arr2 ANYARRAY) 302 | RETURNS boolean[] 303 | AS 'SELECT array_compare_array($1,$2,''>='')' 304 | LANGUAGE 'sql' 305 | IMMUTABLE STRICT; 306 | 307 | CREATE OPERATOR @>= ( 308 | LEFTARG = anyarray, 309 | RIGHTARG = anyarray, 310 | PROCEDURE = array_gte_array 311 | ); 312 | 313 | 314 | CREATE OR REPLACE FUNCTION array_math_array(arr1 ANYARRAY, arr2 ANYARRAY, op TEXT) 315 | RETURNS anyarray 316 | AS 'MODULE_PATHNAME' 317 | LANGUAGE 'c' 318 | IMMUTABLE STRICT; 319 | 320 | CREATE OR REPLACE FUNCTION array_plus_array(arr1 ANYARRAY, arr2 ANYARRAY) 321 | RETURNS anyarray 322 | AS 'SELECT array_math_array($1,$2,''+'')' 323 | LANGUAGE 'sql' 324 | IMMUTABLE STRICT; 325 | 326 | CREATE OPERATOR @+ ( 327 | LEFTARG = anyarray, 328 | RIGHTARG = anyarray, 329 | PROCEDURE = array_plus_array 330 | ); 331 | 332 | CREATE OR REPLACE FUNCTION array_minus_array(arr1 ANYARRAY, arr2 ANYARRAY) 333 | RETURNS anyarray 334 | AS 'SELECT array_math_array($1,$2,''-'')' 335 | LANGUAGE 'sql' 336 | IMMUTABLE STRICT; 337 | 338 | CREATE OPERATOR @- ( 339 | LEFTARG = anyarray, 340 | RIGHTARG = anyarray, 341 | PROCEDURE = array_minus_array 342 | ); 343 | 344 | CREATE OR REPLACE FUNCTION array_times_array(arr1 ANYARRAY, arr2 ANYARRAY) 345 | RETURNS anyarray 346 | AS 'SELECT array_math_array($1,$2,''*'')' 347 | LANGUAGE 'sql' 348 | IMMUTABLE STRICT; 349 | 350 | CREATE OPERATOR @* ( 351 | LEFTARG = anyarray, 352 | RIGHTARG = anyarray, 353 | PROCEDURE = array_times_array 354 | ); 355 | 356 | CREATE OR REPLACE FUNCTION array_div_array(arr1 ANYARRAY, arr2 ANYARRAY) 357 | RETURNS anyarray 358 | AS 'SELECT array_math_array($1,$2,''/'')' 359 | LANGUAGE 'sql' 360 | IMMUTABLE STRICT; 361 | 362 | CREATE OPERATOR @/ ( 363 | LEFTARG = anyarray, 364 | RIGHTARG = anyarray, 365 | PROCEDURE = array_div_array 366 | ); 367 | 368 | 369 | CREATE OR REPLACE FUNCTION array_sum(arr anyarray) 370 | RETURNS ANYELEMENT 371 | AS 'MODULE_PATHNAME' 372 | LANGUAGE 'c' 373 | IMMUTABLE STRICT; 374 | 375 | CREATE OR REPLACE FUNCTION array_avg(arr anyarray) 376 | RETURNS float8 377 | AS 'MODULE_PATHNAME' 378 | LANGUAGE 'c' 379 | IMMUTABLE STRICT; 380 | 381 | CREATE OR REPLACE FUNCTION array_median(arr anyarray) 382 | RETURNS float8 383 | AS 'MODULE_PATHNAME' 384 | LANGUAGE 'c' 385 | IMMUTABLE STRICT; 386 | 387 | CREATE OR REPLACE FUNCTION array_min(arr anyarray) 388 | RETURNS ANYELEMENT 389 | AS 'MODULE_PATHNAME' 390 | LANGUAGE 'c' 391 | IMMUTABLE STRICT; 392 | 393 | CREATE OR REPLACE FUNCTION array_max(arr anyarray) 394 | RETURNS ANYELEMENT 395 | AS 'MODULE_PATHNAME' 396 | LANGUAGE 'c' 397 | IMMUTABLE STRICT; 398 | 399 | CREATE OR REPLACE FUNCTION array_sort(arr anyarray, reverse boolean DEFAULT false) 400 | RETURNS ANYARRAY 401 | AS 'MODULE_PATHNAME' 402 | LANGUAGE 'c' 403 | IMMUTABLE STRICT; 404 | -------------------------------------------------------------------------------- /arraymath.c: -------------------------------------------------------------------------------- 1 | /*********************************************************************** 2 | * 3 | * Project: Array Math 4 | * Purpose: Main file. 5 | * 6 | *********************************************************************** 7 | * Copyright 2012 Paul Ramsey 8 | * 9 | * Permission is hereby granted, free of charge, to any person obtaining a 10 | * copy of this software and associated documentation files (the 11 | * "Software"), to deal in the Software without restriction, including 12 | * without limitation the rights to use, copy, modify, merge, publish, 13 | * distribute, sublicense, and/or sell copies of the Software, and to 14 | * permit persons to whom the Software is furnished to do so, subject to 15 | * the following conditions: 16 | * 17 | * The above copyright notice and this permission notice shall be included 18 | * in all copies or substantial portions of the Software. 19 | * 20 | * THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS 21 | * OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 22 | * MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. 23 | * IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY 24 | * CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, 25 | * TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE 26 | * SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 27 | * 28 | ***********************************************************************/ 29 | 30 | #define ARRAYMATH_VERSION "1.1" 31 | 32 | 33 | /* PostgreSQL */ 34 | #include 35 | #include 36 | #include 37 | #include 38 | 39 | /* Include for VARATT_EXTERNAL_GET_POINTER */ 40 | #if PG_VERSION_NUM < 130000 41 | # include 42 | #else 43 | # include 44 | #endif 45 | 46 | #include 47 | #include 48 | #include 49 | #include 50 | #include 51 | #include 52 | #include 53 | #include 54 | #include 55 | #include 56 | 57 | 58 | /********************************************************************** 59 | * PostgreSQL initialization routines 60 | */ 61 | 62 | /* Set up PgSQL */ 63 | PG_MODULE_MAGIC; 64 | 65 | /* Startup */ 66 | void _PG_init(void); 67 | void _PG_init(void) 68 | { 69 | elog(NOTICE, "Hello from ArrayMath %s", ARRAYMATH_VERSION); 70 | } 71 | 72 | /* Tear-down */ 73 | void _PG_fini(void); 74 | void _PG_fini(void) 75 | { 76 | elog(NOTICE, "Goodbye from ArrayMath %s", ARRAYMATH_VERSION); 77 | } 78 | 79 | 80 | /********************************************************************** 81 | * Utility macros 82 | */ 83 | 84 | #define ARRISEMPTY(x) (ARRNELEMS(x) == 0) 85 | 86 | #define BITMAP_GET(bitmap, i) (bitmap && (bitmap[(i)/sizeof(bits8)] & (1 << ((i) % sizeof(bits8))))) 87 | 88 | #define BITMAP_INCREMENT(bitmap, bitmask) do { \ 89 | if (bitmap) { \ 90 | bitmask <<= 1; \ 91 | if (bitmask == 0x100) { \ 92 | bitmap++; bitmask = 1; \ 93 | } } } while(0); 94 | 95 | #define BITMAP_ISNULL(bitmap, bitmask) (bitmap && (*bitmap & bitmask) == 0) 96 | 97 | /********************************************************************** 98 | * Functions 99 | */ 100 | 101 | static void 102 | arraymath_check_type(Oid elmtype) 103 | { 104 | /* Initialize result value */ 105 | if (elmtype != INT2OID && 106 | elmtype != INT4OID && 107 | elmtype != INT8OID && 108 | elmtype != FLOAT4OID && 109 | elmtype != FLOAT8OID && 110 | elmtype != NUMERICOID) 111 | { 112 | ereport(ERROR, ( 113 | errmsg( 114 | "Array type must be NUMERIC, SMALLINT, INTEGER, BIGINT, REAL, or DOUBLE PRECISION" 115 | ))); 116 | } 117 | } 118 | 119 | static ArrayIterator 120 | arraymath_create_iterator(ArrayType *arr) 121 | { 122 | #if PG_VERSION_NUM >= 90500 123 | return array_create_iterator(arr, 0, NULL); 124 | #else 125 | return array_create_iterator(arr, 0); 126 | #endif 127 | } 128 | 129 | static Numeric 130 | arraymath_int64_to_numeric(int64 i) 131 | { 132 | #if PG_VERSION_NUM >= 140000 133 | return int64_to_numeric(i); 134 | #else 135 | return DatumGetNumeric(Int64GetDatum(i)); 136 | #endif 137 | } 138 | 139 | 140 | /* 141 | * Given an operator symbol ("+", "-", "=" etc) and type element types, 142 | * try to look up the appropriate function to do element level operations of 143 | * that type. 144 | */ 145 | static void 146 | arraymath_fmgrinfo_from_optype(const char *opstr, Oid element_type1, 147 | Oid element_type2, FmgrInfo *operfmgrinfo, Oid *return_type) 148 | { 149 | Oid operator_oid; 150 | HeapTuple opertup; 151 | Form_pg_operator operform; 152 | 153 | /* Look up the operator Oid that corresponds to this combination */ 154 | /* of symbol and data types */ 155 | operator_oid = OpernameGetOprid(list_make1(makeString(pstrdup(opstr))), element_type1, element_type2); 156 | if ( ! (operator_oid && OperatorIsVisible(operator_oid)) ) 157 | { 158 | elog(ERROR, "operator does not exist"); 159 | } 160 | 161 | /* Lookup the function associated with the operator Oid */ 162 | opertup = SearchSysCache1(OPEROID, ObjectIdGetDatum(operator_oid)); 163 | if (! HeapTupleIsValid(opertup)) 164 | { 165 | elog(ERROR, "cannot find operator heap tuple"); 166 | } 167 | 168 | operform = (Form_pg_operator) GETSTRUCT(opertup); 169 | *return_type = operform->oprresult; 170 | 171 | fmgr_info(operform->oprcode, operfmgrinfo); 172 | ReleaseSysCache(opertup); 173 | 174 | return; 175 | } 176 | 177 | 178 | /* 179 | * Given an a source and target type, look up the casting function. 180 | */ 181 | static void 182 | arraymath_fmgrinfo_from_cast(Oid castSrcType, Oid castDstType, FmgrInfo *castfmgrinfo) 183 | { 184 | HeapTuple casttup; 185 | Form_pg_cast castform; 186 | 187 | /* Lookup the function associated with the operator Oid */ 188 | casttup = SearchSysCache2(CASTSOURCETARGET, 189 | ObjectIdGetDatum(castSrcType), 190 | ObjectIdGetDatum(castDstType)); 191 | 192 | if (! HeapTupleIsValid(casttup)) 193 | { 194 | elog(ERROR, "cannot find cast from %s to %s", 195 | format_type_be(castSrcType), 196 | format_type_be(castDstType)); 197 | } 198 | 199 | castform = (Form_pg_cast) GETSTRUCT(casttup); 200 | fmgr_info(castform->castfunc, castfmgrinfo); 201 | ReleaseSysCache(casttup); 202 | 203 | return; 204 | } 205 | 206 | 207 | /* 208 | * Read type information for a given element type. 209 | */ 210 | static TypeCacheEntry * 211 | arraymath_typentry_from_type(Oid element_type, int flags) 212 | { 213 | TypeCacheEntry *typentry; 214 | typentry = lookup_type_cache(element_type, flags); 215 | if (!typentry) 216 | { 217 | elog(ERROR, "unable to lookup element type info for %s", 218 | format_type_be(element_type)); 219 | } 220 | return typentry; 221 | } 222 | 223 | 224 | /* 225 | * Apply an operator using an element over all the elements 226 | * of an array. 227 | */ 228 | static ArrayType * 229 | arraymath_array_oper_elem(ArrayType *array1, const char *opname, Datum element2, Oid element_type2) 230 | { 231 | ArrayType *array_out; 232 | int dims[1]; 233 | int lbs[1]; 234 | Datum *elems; 235 | bool *nulls; 236 | 237 | int ndims1 = ARR_NDIM(array1); 238 | int *dims1 = ARR_DIMS(array1); 239 | Oid element_type1 = ARR_ELEMTYPE(array1); 240 | Oid rtype; 241 | int nelems, n = 0; 242 | FmgrInfo operfmgrinfo; 243 | TypeCacheEntry *tinfo; 244 | ArrayIterator iterator1; 245 | Datum element1; 246 | bool isnull1; 247 | 248 | /* Only 1D arrays for now */ 249 | if (ndims1 != 1) 250 | { 251 | elog(ERROR, "only one-dimensional arrays are supported"); 252 | return NULL; 253 | } 254 | 255 | /* What function works for these input types? Populate operfmgrinfo. */ 256 | /* What data type will the output array be? */ 257 | arraymath_fmgrinfo_from_optype(opname, element_type1, element_type2, &operfmgrinfo, &rtype); 258 | 259 | /* How big is the output array? */ 260 | nelems = ArrayGetNItems(ndims1, dims1); 261 | 262 | /* If input is empty, return empty */ 263 | if (nelems == 0) 264 | { 265 | return construct_empty_array(rtype); 266 | } 267 | 268 | iterator1 = arraymath_create_iterator(array1); 269 | 270 | /* Allocate space for output data */ 271 | elems = palloc(sizeof(Datum)*nelems); 272 | nulls = palloc(sizeof(bool)*nelems); 273 | 274 | while (array_iterate(iterator1, &element1, &isnull1)) 275 | { 276 | if (isnull1) 277 | { 278 | nulls[n] = true; 279 | elems[n] = (Datum) 0; 280 | } 281 | else 282 | { 283 | /* Apply the operator */ 284 | nulls[n] = false; 285 | elems[n] = FunctionCall2(&operfmgrinfo, element1, element2); 286 | } 287 | n++; 288 | } 289 | 290 | /* Build 1-d output array */ 291 | tinfo = arraymath_typentry_from_type(rtype, 0); 292 | dims[0] = nelems; 293 | lbs[0] = 1; 294 | array_out = construct_md_array(elems, nulls, 1, dims, lbs, rtype, tinfo->typlen, tinfo->typbyval, tinfo->typalign); 295 | 296 | /* Output is supposed to be a copy, so free the inputs */ 297 | pfree(elems); 298 | pfree(nulls); 299 | 300 | /* Make sure we haven't been given garbage */ 301 | if (!array_out) 302 | { 303 | elog(ERROR, "unable to construct output array"); 304 | return NULL; 305 | } 306 | 307 | return array_out; 308 | } 309 | 310 | /* 311 | * Apply an operator over all the elements of a pair of arrays 312 | * expanding to return an array of the same size as the largest 313 | * input array. 314 | */ 315 | static ArrayType * 316 | arraymath_array_oper_array(ArrayType *array1, const char *opname, ArrayType *array2) 317 | { 318 | ArrayType *array_out; 319 | int dims[1]; 320 | int lbs[1]; 321 | Datum *elems; 322 | bool *nulls; 323 | 324 | int ndims1 = ARR_NDIM(array1); 325 | int ndims2 = ARR_NDIM(array2); 326 | int *dims1 = ARR_DIMS(array1); 327 | int *dims2 = ARR_DIMS(array2); 328 | char *ptr1 = NULL, *ptr2 = NULL; 329 | Oid element_type1 = ARR_ELEMTYPE(array1); 330 | Oid element_type2 = ARR_ELEMTYPE(array2); 331 | Oid rtype; 332 | int nitems1, nitems2; 333 | int nelems, n; 334 | bits8 *bitmap1 = NULL, *bitmap2 = NULL; 335 | int bitmask1 = 0, bitmask2 = 0; 336 | FmgrInfo operfmgrinfo; 337 | TypeCacheEntry *info1, *info2, *tinfo; 338 | 339 | if ( ndims1 == 0 && ndims2 == 1 ) 340 | { 341 | return array2; 342 | } 343 | else if ( ndims1 == 1 && ndims2 == 0 ) 344 | { 345 | return array1; 346 | } 347 | else if ( ndims1 == 0 && ndims2 == 0 ) 348 | { 349 | return construct_empty_array(element_type1); 350 | } 351 | 352 | /* Only 1D arrays for now */ 353 | if ( ndims1 != 1 || ndims2 != 1 ) 354 | { 355 | elog(ERROR, "only 1-dimensional arrays supported"); 356 | return NULL; 357 | } 358 | 359 | /* What function works for these input types? Populate operfmgrinfo. */ 360 | /* What data type will the output array be? */ 361 | arraymath_fmgrinfo_from_optype(opname, element_type1, element_type2, &operfmgrinfo, &rtype); 362 | tinfo = arraymath_typentry_from_type(rtype, 0); 363 | 364 | /* How big is the output array? */ 365 | nitems1 = ArrayGetNItems(ndims1, dims1); 366 | nitems2 = ArrayGetNItems(ndims2, dims2); 367 | nelems = Max(nitems1, nitems2); 368 | 369 | /* If either input is empty, return empty */ 370 | if ( nitems1 == 0 || nitems2 == 0 ) 371 | { 372 | return construct_empty_array(rtype); 373 | } 374 | 375 | /* Allocate space for output data */ 376 | elems = palloc(sizeof(Datum)*nelems); 377 | nulls = palloc(sizeof(bool)*nelems); 378 | 379 | /* Learn more about the input arrays */ 380 | info1 = arraymath_typentry_from_type(element_type1, 0); 381 | info2 = arraymath_typentry_from_type(element_type2, 0); 382 | 383 | /* Loop over all the items, re-using items from the shorter */ 384 | /* array to apply to the longer */ 385 | for( n = 0; n < nelems; n++ ) 386 | { 387 | Datum elt1, elt2; 388 | int i1 = n % nitems1; 389 | int i2 = n % nitems2; 390 | bool isnull1, isnull2; 391 | 392 | /* Initialize array pointers at start of loop, and */ 393 | /* on wrap-around */ 394 | if ( i1 == 0 ) 395 | { 396 | ptr1 = ARR_DATA_PTR(array1); 397 | bitmap1 = ARR_NULLBITMAP(array1); 398 | bitmask1 = 1; 399 | } 400 | 401 | if ( i2 == 0 ) 402 | { 403 | ptr2 = ARR_DATA_PTR(array2); 404 | bitmap2 = ARR_NULLBITMAP(array2); 405 | bitmask2 = 1; 406 | } 407 | 408 | /* Check null status */ 409 | isnull1 = BITMAP_ISNULL(bitmap1, bitmask1); 410 | isnull2 = BITMAP_ISNULL(bitmap2, bitmask2); 411 | 412 | /* Start with NULL values */ 413 | elt1 = elt2 = (Datum) 0; 414 | 415 | if ( ! isnull1 ) 416 | { 417 | /* Read the element value */ 418 | elt1 = fetch_att(ptr1, info1->typbyval, info1->typlen); 419 | 420 | /* Move the pointer forward */ 421 | ptr1 = att_addlength_pointer(ptr1, info1->typlen, ptr1); 422 | ptr1 = (char *) att_align_nominal(ptr1, info1->typalign); 423 | } 424 | 425 | if ( ! isnull2 ) 426 | { 427 | /* Read the element value */ 428 | elt2 = fetch_att(ptr2, info2->typbyval, info2->typlen); 429 | 430 | /* Move the pointer forward */ 431 | ptr2 = att_addlength_pointer(ptr2, info2->typlen, ptr2); 432 | ptr2 = (char *) att_align_nominal(ptr2, info2->typalign); 433 | } 434 | 435 | /* NULL on either side of operator yields output NULL */ 436 | if ( isnull1 || isnull2 ) 437 | { 438 | nulls[n] = true; 439 | elems[n] = (Datum) 0; 440 | } 441 | else 442 | { 443 | nulls[n] = false; 444 | elems[n] = FunctionCall2(&operfmgrinfo, elt1, elt2); 445 | } 446 | 447 | BITMAP_INCREMENT(bitmap1, bitmask1); 448 | BITMAP_INCREMENT(bitmap2, bitmask2); 449 | } 450 | 451 | /* Build 1-d output array */ 452 | dims[0] = nelems; 453 | lbs[0] = 1; 454 | array_out = construct_md_array(elems, nulls, 1, dims, lbs, rtype, tinfo->typlen, tinfo->typbyval, tinfo->typalign); 455 | 456 | /* Output is supposed to be a copy, so free the inputs */ 457 | pfree(elems); 458 | pfree(nulls); 459 | 460 | /* Make sure we haven't been given garbage */ 461 | if ( ! array_out ) 462 | { 463 | elog(ERROR, "unable to construct output array"); 464 | return NULL; 465 | } 466 | 467 | return array_out; 468 | } 469 | 470 | /* 471 | * Compare two arrays. 472 | */ 473 | Datum array_compare_array(PG_FUNCTION_ARGS); 474 | PG_FUNCTION_INFO_V1(array_compare_array); 475 | Datum array_compare_array(PG_FUNCTION_ARGS) 476 | { 477 | ArrayType *array1 = PG_GETARG_ARRAYTYPE_P(0); 478 | ArrayType *array2 = PG_GETARG_ARRAYTYPE_P(1); 479 | text *operator = PG_GETARG_TEXT_P(2); 480 | char *opname = text_to_cstring(operator); 481 | ArrayType *arrayout; 482 | 483 | arrayout = arraymath_array_oper_array(array1, opname, array2); 484 | 485 | PG_FREE_IF_COPY(array1, 0); 486 | PG_FREE_IF_COPY(array2, 1); 487 | 488 | PG_RETURN_ARRAYTYPE_P(arrayout); 489 | } 490 | 491 | 492 | /* 493 | * Operator on two arrays. 494 | */ 495 | Datum array_math_array(PG_FUNCTION_ARGS); 496 | PG_FUNCTION_INFO_V1(array_math_array); 497 | Datum array_math_array(PG_FUNCTION_ARGS) 498 | { 499 | ArrayType *array1 = PG_GETARG_ARRAYTYPE_P(0); 500 | ArrayType *array2 = PG_GETARG_ARRAYTYPE_P(1); 501 | text *operator = PG_GETARG_TEXT_P(2); 502 | char *opname = text_to_cstring(operator); 503 | ArrayType *arrayout; 504 | 505 | arrayout = arraymath_array_oper_array(array1, opname, array2); 506 | 507 | PG_FREE_IF_COPY(array1, 0); 508 | PG_FREE_IF_COPY(array2, 1); 509 | 510 | PG_RETURN_ARRAYTYPE_P(arrayout); 511 | } 512 | 513 | 514 | 515 | /* 516 | * Compare an array to a constant element 517 | */ 518 | Datum array_compare_value(PG_FUNCTION_ARGS); 519 | PG_FUNCTION_INFO_V1(array_compare_value); 520 | Datum array_compare_value(PG_FUNCTION_ARGS) 521 | { 522 | ArrayType *array1 = PG_GETARG_ARRAYTYPE_P(0); 523 | Datum element2 = PG_GETARG_DATUM(1); 524 | text *operator = PG_GETARG_TEXT_P(2); 525 | char *opname = text_to_cstring(operator); 526 | Oid element_type2; 527 | ArrayType *arrayout; 528 | 529 | element_type2 = get_fn_expr_argtype(fcinfo->flinfo, 1); 530 | arrayout = arraymath_array_oper_elem(array1, opname, element2, element_type2); 531 | 532 | PG_FREE_IF_COPY(array1, 0); 533 | PG_RETURN_ARRAYTYPE_P(arrayout); 534 | } 535 | 536 | /* 537 | * Do math on an array using a constant element 538 | */ 539 | Datum array_math_value(PG_FUNCTION_ARGS); 540 | PG_FUNCTION_INFO_V1(array_math_value); 541 | Datum array_math_value(PG_FUNCTION_ARGS) 542 | { 543 | ArrayType *array1 = PG_GETARG_ARRAYTYPE_P(0); 544 | Datum element2 = PG_GETARG_DATUM(1); 545 | text *operator = PG_GETARG_TEXT_P(2); 546 | char *opname = text_to_cstring(operator); 547 | Oid element_type2; 548 | ArrayType *arrayout; 549 | 550 | element_type2 = get_fn_expr_argtype(fcinfo->flinfo, 1); 551 | arrayout = arraymath_array_oper_elem(array1, opname, element2, element_type2); 552 | 553 | PG_FREE_IF_COPY(array1, 0); 554 | PG_RETURN_ARRAYTYPE_P(arrayout); 555 | } 556 | 557 | 558 | static Datum 559 | arraymath_zero(Oid oid) 560 | { 561 | /* Initialize result value */ 562 | if (oid == INT2OID || 563 | oid == INT4OID || 564 | oid == INT8OID || 565 | oid == FLOAT4OID || 566 | oid == FLOAT8OID) 567 | { 568 | /* Ints and Floats store value in the Datum */ 569 | return (Datum)0; 570 | } 571 | else if (oid == NUMERICOID) 572 | { 573 | /* Numeric type is varlena, requires special initialization */ 574 | return NumericGetDatum(arraymath_int64_to_numeric(0)); 575 | } 576 | else 577 | { 578 | ereport(ERROR, (errmsg("Sum subject must be NUMERIC, SMALLINT, INTEGER, BIGINT, REAL, or DOUBLE PRECISION values"))); 579 | } 580 | } 581 | 582 | 583 | static Datum 584 | arraymath_sum(ArrayType *vals, Oid valsType) 585 | { 586 | /* Get + operator FmgrInfo */ 587 | FmgrInfo operfmgrinfo; 588 | Oid rtype; 589 | const char* op = "+"; 590 | Datum v = arraymath_zero(valsType); 591 | Datum elem; 592 | ArrayIterator iterator; 593 | bool isnull; 594 | 595 | arraymath_fmgrinfo_from_optype(op, valsType, valsType, &operfmgrinfo, &rtype); 596 | 597 | iterator = arraymath_create_iterator(vals); 598 | while (array_iterate(iterator, &elem, &isnull)) 599 | { 600 | if (!isnull) 601 | { 602 | /* Apply the operator */ 603 | v = FunctionCall2(&operfmgrinfo, elem, v); 604 | } 605 | } 606 | return v; 607 | } 608 | 609 | 610 | static float8 611 | arraymath_float8(Datum d, Oid typOid) 612 | { 613 | FmgrInfo castfmgrinfo; 614 | Datum v; 615 | arraymath_fmgrinfo_from_cast(typOid, FLOAT8OID, &castfmgrinfo); 616 | v = FunctionCall1(&castfmgrinfo, d); 617 | return DatumGetFloat8(v); 618 | } 619 | 620 | 621 | /* 622 | * Do sum of an array 623 | */ 624 | Datum array_sum(PG_FUNCTION_ARGS); 625 | PG_FUNCTION_INFO_V1(array_sum); 626 | Datum 627 | array_sum(PG_FUNCTION_ARGS) 628 | { 629 | ArrayType *vals = PG_GETARG_ARRAYTYPE_P(0); 630 | Oid valsType = ARR_ELEMTYPE(vals); 631 | Datum result = arraymath_zero(valsType); 632 | size_t valsLength; 633 | 634 | arraymath_check_type(valsType); 635 | 636 | if (ARR_NDIM(vals) == 0) 637 | PG_RETURN_NULL(); 638 | 639 | if (ARR_NDIM(vals) > 1) 640 | ereport(ERROR, (errmsg("only one-dimensional arrays are supported"))); 641 | 642 | /* Empty length return 0 */ 643 | valsLength = (ARR_DIMS(vals))[0]; 644 | if (valsLength > 0) 645 | result = arraymath_sum(vals, valsType); 646 | 647 | PG_RETURN_DATUM(result); 648 | } 649 | 650 | 651 | /* 652 | * Do average of an array 653 | */ 654 | Datum array_avg(PG_FUNCTION_ARGS); 655 | PG_FUNCTION_INFO_V1(array_avg); 656 | Datum 657 | array_avg(PG_FUNCTION_ARGS) 658 | { 659 | ArrayType *vals = PG_GETARG_ARRAYTYPE_P(0); 660 | Oid valsType = ARR_ELEMTYPE(vals); 661 | Datum sumDatum; 662 | float8 sum, count; 663 | size_t valsLength; 664 | 665 | arraymath_check_type(valsType); 666 | 667 | if (ARR_NDIM(vals) == 0) 668 | PG_RETURN_NULL(); 669 | 670 | if (ARR_NDIM(vals) > 1) 671 | ereport(ERROR, (errmsg("only one-dimensional arrays are supported"))); 672 | 673 | valsLength = (ARR_DIMS(vals))[0]; 674 | if (valsLength == 0) 675 | PG_RETURN_NULL(); 676 | 677 | sumDatum = arraymath_sum(vals, valsType); 678 | sum = arraymath_float8(sumDatum, valsType); 679 | 680 | /* array_avg(anyarray) => float8 */ 681 | count = (float8)valsLength; 682 | 683 | /* float8 argument should force float8 return */ 684 | PG_RETURN_FLOAT8(sum / count); 685 | } 686 | 687 | 688 | static Datum 689 | arraymath_minmax(ArrayType *arr, int mode) 690 | { 691 | Oid arrType = ARR_ELEMTYPE(arr); 692 | Datum elem, result = (Datum)0, cmp; 693 | bool isnull, first = true; 694 | TypeCacheEntry *typeCache = arraymath_typentry_from_type(arrType, TYPECACHE_CMP_PROC_FINFO); 695 | FmgrInfo cmpFmgrInfo = typeCache->cmp_proc_finfo; 696 | ArrayIterator iterator; 697 | 698 | arraymath_check_type(arrType); 699 | 700 | iterator = arraymath_create_iterator(arr); 701 | while (array_iterate(iterator, &elem, &isnull)) 702 | { 703 | if (isnull) continue; 704 | 705 | if (first) 706 | { 707 | result = elem; 708 | first = false; 709 | continue; 710 | } 711 | 712 | /* cmp_proc_finfo returns -1 for less than */ 713 | /* and 1 for greater than. Mode is -1 for min */ 714 | /* and 1 for max */ 715 | cmp = FunctionCall2(&cmpFmgrInfo, elem, result); 716 | if ((mode < 0 && DatumGetInt32(cmp) < 0) || 717 | (mode > 0 && DatumGetInt32(cmp) > 0)) 718 | { 719 | result = elem; 720 | } 721 | } 722 | return result; 723 | } 724 | 725 | 726 | /* 727 | * Do minimum of an array 728 | */ 729 | Datum array_min(PG_FUNCTION_ARGS); 730 | PG_FUNCTION_INFO_V1(array_min); 731 | Datum array_min(PG_FUNCTION_ARGS) 732 | { 733 | ArrayType *arr = PG_GETARG_ARRAYTYPE_P(0); 734 | size_t arrLen; 735 | 736 | if (ARR_NDIM(arr) == 0) 737 | PG_RETURN_NULL(); 738 | 739 | if (ARR_NDIM(arr) > 1) 740 | ereport(ERROR, (errmsg("only one-dimensional arrays are supported"))); 741 | 742 | arrLen = (ARR_DIMS(arr))[0]; 743 | if (arrLen == 0) 744 | PG_RETURN_NULL(); 745 | 746 | PG_RETURN_DATUM(arraymath_minmax(arr, -1)); 747 | } 748 | 749 | /* 750 | * Do maximum of an array 751 | */ 752 | Datum array_max(PG_FUNCTION_ARGS); 753 | PG_FUNCTION_INFO_V1(array_max); 754 | Datum array_max(PG_FUNCTION_ARGS) 755 | { 756 | ArrayType *arr = PG_GETARG_ARRAYTYPE_P(0); 757 | size_t arrLen; 758 | 759 | if (ARR_NDIM(arr) == 0) 760 | PG_RETURN_NULL(); 761 | 762 | if (ARR_NDIM(arr) > 1) 763 | ereport(ERROR, (errmsg("only one-dimensional arrays are supported"))); 764 | 765 | arrLen = (ARR_DIMS(arr))[0]; 766 | if (arrLen == 0) 767 | PG_RETURN_NULL(); 768 | 769 | PG_RETURN_DATUM(arraymath_minmax(arr, 1)); 770 | } 771 | 772 | 773 | FmgrInfo* arraySortFmgrinfo; 774 | 775 | static int 776 | arraySortCmp (const void *a, const void *b) 777 | { 778 | int cmp; 779 | Datum da = *((Datum*)a); 780 | Datum db = *((Datum*)b); 781 | 782 | /* Do not try to sort if we don't have a cmp method */ 783 | if (!arraySortFmgrinfo) return 0; 784 | 785 | /* Sort nulls to the start of the list */ 786 | if (! da) return -1; 787 | if (! db) return 1; 788 | 789 | cmp = FunctionCall2(arraySortFmgrinfo, da, db); 790 | return DatumGetInt32(cmp); 791 | } 792 | 793 | static int 794 | arrayRSortCmp (const void *a, const void *b) 795 | { 796 | return arraySortCmp(b, a); 797 | } 798 | 799 | 800 | Datum array_sort(PG_FUNCTION_ARGS); 801 | PG_FUNCTION_INFO_V1(array_sort); 802 | Datum array_sort(PG_FUNCTION_ARGS) 803 | { 804 | ArrayType *arr = PG_GETARG_ARRAYTYPE_P(0); 805 | bool reverse = PG_GETARG_BOOL(1); 806 | ArrayType *arrOut; 807 | Oid elmtype = ARR_ELEMTYPE(arr); 808 | TypeCacheEntry *typeCache = arraymath_typentry_from_type(elmtype, TYPECACHE_CMP_PROC_FINFO); 809 | FmgrInfo cmpFmgrInfo = typeCache->cmp_proc_finfo; 810 | 811 | int nelems; 812 | Datum* elems; 813 | bool* nulls; 814 | 815 | int dims[1]; 816 | int lbs[1]; 817 | 818 | arraymath_check_type(elmtype); 819 | 820 | if (ARR_NDIM(arr) == 0) 821 | PG_RETURN_ARRAYTYPE_P(arr); 822 | 823 | if (ARR_NDIM(arr) > 1) 824 | ereport(ERROR, (errmsg("only one-dimensional arrays are supported"))); 825 | 826 | nelems = (ARR_DIMS(arr))[0]; 827 | if (nelems == 0) 828 | PG_RETURN_ARRAYTYPE_P(arr); 829 | 830 | deconstruct_array(arr, elmtype, 831 | typeCache->typlen, typeCache->typbyval, typeCache->typalign, 832 | &elems, &nulls, &nelems); 833 | 834 | dims[0] = nelems; 835 | lbs[0] = 1; 836 | 837 | arraySortFmgrinfo = &cmpFmgrInfo; 838 | if (reverse) 839 | qsort(elems, nelems, sizeof(Datum), arrayRSortCmp); 840 | else 841 | qsort(elems, nelems, sizeof(Datum), arraySortCmp); 842 | 843 | for (int i = 0; i < nelems; i++) 844 | { 845 | nulls[i] = (elems[i] == (Datum)0); 846 | } 847 | 848 | arrOut = construct_md_array(elems, nulls, 849 | 1, dims, lbs, elmtype, 850 | typeCache->typlen, typeCache->typbyval, typeCache->typalign); 851 | 852 | PG_RETURN_ARRAYTYPE_P(arrOut); 853 | } 854 | 855 | 856 | /* 857 | * Do average of an array 858 | */ 859 | Datum array_median(PG_FUNCTION_ARGS); 860 | PG_FUNCTION_INFO_V1(array_median); 861 | Datum 862 | array_median(PG_FUNCTION_ARGS) 863 | { 864 | Datum arrSorted = DirectFunctionCall2(array_sort, 865 | PG_GETARG_DATUM(0), BoolGetDatum(false)); 866 | ArrayType *arr = DatumGetArrayTypeP(arrSorted); 867 | Oid elmtype = ARR_ELEMTYPE(arr); 868 | TypeCacheEntry *typeCache = arraymath_typentry_from_type(elmtype, 0); 869 | TypeCacheEntry *arrTypeCache = arraymath_typentry_from_type(get_fn_expr_argtype(fcinfo->flinfo, 0), 0); 870 | size_t nelems; 871 | 872 | Datum v0, v1; 873 | FmgrInfo castfmgrinfo; 874 | bool isnull; 875 | int idx[1]; 876 | 877 | arraymath_check_type(elmtype); 878 | 879 | if ((!arr) || ARR_NDIM(arr) == 0) 880 | PG_RETURN_NULL(); 881 | 882 | if (ARR_NDIM(arr) > 1) 883 | ereport(ERROR, (errmsg("only one-dimensional arrays are supported"))); 884 | 885 | nelems = (ARR_DIMS(arr))[0]; 886 | if (nelems == 0) 887 | PG_RETURN_NULL(); 888 | 889 | arraymath_fmgrinfo_from_cast(elmtype, FLOAT8OID, &castfmgrinfo); 890 | 891 | /* Odd number of elements */ 892 | if (nelems % 2) 893 | { 894 | idx[0] = (nelems + 1) / 2; 895 | v0 = array_get_element(arrSorted, 1, idx, arrTypeCache->typlen, 896 | typeCache->typlen, typeCache->typbyval, typeCache->typalign, 897 | &isnull); 898 | PG_RETURN_DATUM(FunctionCall1(&castfmgrinfo, v0)); 899 | } 900 | else 901 | { 902 | float8 f0, f1, median; 903 | idx[0] = (nelems / 2) + 1; 904 | v0 = array_get_element(arrSorted, 1, idx, arrTypeCache->typlen, 905 | typeCache->typlen, typeCache->typbyval, typeCache->typalign, 906 | &isnull); 907 | idx[0] = (nelems / 2); 908 | v1 = array_get_element(arrSorted, 1, idx, arrTypeCache->typlen, 909 | typeCache->typlen, typeCache->typbyval, typeCache->typalign, 910 | &isnull); 911 | f0 = DatumGetFloat8(FunctionCall1(&castfmgrinfo, v0)); 912 | f1 = DatumGetFloat8(FunctionCall1(&castfmgrinfo, v1)); 913 | median = (f0 + f1) / 2.0; 914 | PG_RETURN_FLOAT8(median); 915 | } 916 | } 917 | -------------------------------------------------------------------------------- /arraymath.control: -------------------------------------------------------------------------------- 1 | default_version = '1.1' 2 | module_pathname = '$libdir/arraymath' 3 | relocatable = true 4 | comment = 'Array math and operators that work element by element on the contents of arrays.' 5 | -------------------------------------------------------------------------------- /ci/pg_hba.conf: -------------------------------------------------------------------------------- 1 | # TYPE DATABASE USER ADDRESS METHOD 2 | 3 | # "local" is for Unix domain socket connections only 4 | local all postgres trust 5 | # IPv4 local connections: 6 | host all postgres 127.0.0.1/32 trust 7 | # IPv6 local connections: 8 | host all postgres ::1/128 trust 9 | -------------------------------------------------------------------------------- /expected/arraymath.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION arraymath; 2 | SELECT ARRAY[1,2,3,4] @< 4 3 | AS array_lt_constant; 4 | array_lt_constant 5 | ------------------- 6 | {t,t,t,f} 7 | (1 row) 8 | 9 | SELECT ARRAY[3.4,5.6,7.6] @* 8.1 10 | AS array_times_constant; 11 | array_times_constant 12 | ---------------------- 13 | {27.54,45.36,61.56} 14 | (1 row) 15 | 16 | SELECT ARRAY[1,2] @+ ARRAY[3,4] 17 | AS array_plus_array; 18 | array_plus_array 19 | ------------------ 20 | {4,6} 21 | (1 row) 22 | 23 | SELECT ARRAY[1,2,3,4,5,6] @* ARRAY[1,2] 24 | AS array_times_array; 25 | array_times_array 26 | ------------------- 27 | {1,4,3,8,5,12} 28 | (1 row) 29 | 30 | SELECT ARRAY[1,1,1,1] @< ARRAY[0,2] 31 | AS array_lt_array; 32 | array_lt_array 33 | ---------------- 34 | {f,t,f,t} 35 | (1 row) 36 | 37 | SELECT ARRAY[1,2,3] @= ARRAY[3,2,1] 38 | AS array_eq_array; 39 | array_eq_array 40 | ---------------- 41 | {f,t,f} 42 | (1 row) 43 | 44 | WITH a AS ( 45 | SELECT array_agg(a) AS b FROM generate_series(1,100) a 46 | ) 47 | SELECT b @+ b 48 | AS array_plus_array_lg FROM a; 49 | array_plus_array_lg 50 | -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 51 | {2,4,6,8,10,12,14,16,18,20,22,24,26,28,30,32,34,36,38,40,42,44,46,48,50,52,54,56,58,60,62,64,66,68,70,72,74,76,78,80,82,84,86,88,90,92,94,96,98,100,102,104,106,108,110,112,114,116,118,120,122,124,126,128,130,132,134,136,138,140,142,144,146,148,150,152,154,156,158,160,162,164,166,168,170,172,174,176,178,180,182,184,186,188,190,192,194,196,198,200} 52 | (1 row) 53 | 54 | WITH a AS ( 55 | SELECT array_agg(a) AS b FROM generate_series(1,100) a 56 | ) 57 | SELECT b @+ ARRAY[0,1] 58 | AS array_plus_array_sm FROM a; 59 | array_plus_array_sm 60 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 61 | {1,3,3,5,5,7,7,9,9,11,11,13,13,15,15,17,17,19,19,21,21,23,23,25,25,27,27,29,29,31,31,33,33,35,35,37,37,39,39,41,41,43,43,45,45,47,47,49,49,51,51,53,53,55,55,57,57,59,59,61,61,63,63,65,65,67,67,69,69,71,71,73,73,75,75,77,77,79,79,81,81,83,83,85,85,87,87,89,89,91,91,93,93,95,95,97,97,99,99,101} 62 | (1 row) 63 | 64 | SELECT ARRAY[1,1,1,1] @< ARRAY[1,NULL,1,1] 65 | AS array_lt_array_null; 66 | array_lt_array_null 67 | --------------------- 68 | {f,NULL,f,f} 69 | (1 row) 70 | 71 | SELECT ARRAY[NULL] @< ARRAY[NULL] 72 | AS array_lt_array_nullnull; 73 | array_lt_array_nullnull 74 | ------------------------- 75 | {NULL} 76 | (1 row) 77 | 78 | SELECT ARRAY[[1,2,3],[1,2]] @+ 1 79 | AS array_2d_err; 80 | ERROR: multidimensional arrays must have array expressions with matching dimensions 81 | SELECT ARRAY[]::integer[] @< ARRAY[NULL]::integer[] 82 | AS array_null_error_a; 83 | array_null_error_a 84 | -------------------- 85 | {NULL} 86 | (1 row) 87 | 88 | SELECT ARRAY[NULL]::integer[] @< ARRAY[]::integer[] 89 | AS array_null_error_b; 90 | array_null_error_b 91 | -------------------- 92 | {NULL} 93 | (1 row) 94 | 95 | WITH a AS ( 96 | SELECT array_cat(array_agg(a), ARRAY[NULL,NULL]::int4[]) AS b FROM generate_series(1,10) a 97 | ) 98 | SELECT 99 | array_sum(b) AS array_sum, 100 | array_min(b) AS array_min, 101 | array_max(b) AS array_max, 102 | array_avg(b) AS array_avg, 103 | array_median(b) AS array_median, 104 | array_sort(b) AS array_sort, 105 | array_sort(b, true) AS array_rsort 106 | FROM a; 107 | array_sum | array_min | array_max | array_avg | array_median | array_sort | array_rsort 108 | -----------+-----------+-----------+-------------------+--------------+----------------------------------+---------------------------------- 109 | 55 | 1 | 10 | 4.583333333333333 | 4.5 | {NULL,NULL,1,2,3,4,5,6,7,8,9,10} | {10,9,8,7,6,5,4,3,2,1,NULL,NULL} 110 | (1 row) 111 | 112 | -------------------------------------------------------------------------------- /sql/arraymath.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION arraymath; 2 | 3 | SELECT ARRAY[1,2,3,4] @< 4 4 | AS array_lt_constant; 5 | 6 | SELECT ARRAY[3.4,5.6,7.6] @* 8.1 7 | AS array_times_constant; 8 | 9 | SELECT ARRAY[1,2] @+ ARRAY[3,4] 10 | AS array_plus_array; 11 | 12 | SELECT ARRAY[1,2,3,4,5,6] @* ARRAY[1,2] 13 | AS array_times_array; 14 | 15 | SELECT ARRAY[1,1,1,1] @< ARRAY[0,2] 16 | AS array_lt_array; 17 | 18 | SELECT ARRAY[1,2,3] @= ARRAY[3,2,1] 19 | AS array_eq_array; 20 | 21 | WITH a AS ( 22 | SELECT array_agg(a) AS b FROM generate_series(1,100) a 23 | ) 24 | SELECT b @+ b 25 | AS array_plus_array_lg FROM a; 26 | 27 | WITH a AS ( 28 | SELECT array_agg(a) AS b FROM generate_series(1,100) a 29 | ) 30 | SELECT b @+ ARRAY[0,1] 31 | AS array_plus_array_sm FROM a; 32 | 33 | SELECT ARRAY[1,1,1,1] @< ARRAY[1,NULL,1,1] 34 | AS array_lt_array_null; 35 | 36 | SELECT ARRAY[NULL] @< ARRAY[NULL] 37 | AS array_lt_array_nullnull; 38 | 39 | SELECT ARRAY[[1,2,3],[1,2]] @+ 1 40 | AS array_2d_err; 41 | 42 | SELECT ARRAY[]::integer[] @< ARRAY[NULL]::integer[] 43 | AS array_null_error_a; 44 | 45 | SELECT ARRAY[NULL]::integer[] @< ARRAY[]::integer[] 46 | AS array_null_error_b; 47 | 48 | WITH a AS ( 49 | SELECT array_cat(array_agg(a), ARRAY[NULL,NULL]::int4[]) AS b FROM generate_series(1,10) a 50 | ) 51 | SELECT 52 | array_sum(b) AS array_sum, 53 | array_min(b) AS array_min, 54 | array_max(b) AS array_max, 55 | array_avg(b) AS array_avg, 56 | array_median(b) AS array_median, 57 | array_sort(b) AS array_sort, 58 | array_sort(b, true) AS array_rsort 59 | FROM a; 60 | 61 | 62 | --------------------------------------------------------------------------------