├── .github └── workflows │ ├── ci.yml │ └── release.yml ├── .gitignore ├── LICENSE ├── META.json ├── Makefile ├── README.md ├── quantile.c ├── quantile.control ├── sql ├── quantile--1.1.4--1.1.5.sql ├── quantile--1.1.5--1.1.6.sql ├── quantile--1.1.6--1.1.7.sql ├── quantile--1.1.7--1.1.8.sql └── quantile--1.1.8.sql └── test ├── expected └── base.out └── sql └── base.sql /.github/workflows/ci.yml: -------------------------------------------------------------------------------- 1 | name: make installcheck 2 | on: [push, pull_request] 3 | jobs: 4 | test: 5 | strategy: 6 | matrix: 7 | pg: [17, 16, 15, 14, 13, 12, 11, 10, 9.6] 8 | name: PostgreSQL ${{ matrix.pg }} 9 | runs-on: ubuntu-latest 10 | container: pgxn/pgxn-tools 11 | steps: 12 | 13 | - name: Start PostgreSQL ${{ matrix.pg }} 14 | run: pg-start ${{ matrix.pg }} 15 | 16 | - name: Check out the repo 17 | uses: actions/checkout@v2 18 | 19 | - name: Test on PostgreSQL ${{ matrix.pg }} 20 | run: pg-build-test 21 | -------------------------------------------------------------------------------- /.github/workflows/release.yml: -------------------------------------------------------------------------------- 1 | name: Release 2 | on: 3 | push: 4 | tags: [v*] 5 | jobs: 6 | release: 7 | name: Release on GitHub and PGXN 8 | runs-on: ubuntu-latest 9 | container: pgxn/pgxn-tools 10 | env: 11 | GITHUB_TOKEN: ${{ secrets.GITHUB_TOKEN }} 12 | PGXN_USERNAME: ${{ secrets.PGXN_USERNAME }} 13 | PGXN_PASSWORD: ${{ secrets.PGXN_PASSWORD }} 14 | steps: 15 | - name: Check out the repo 16 | uses: actions/checkout@v4 17 | - name: Install required packages 18 | run: | 19 | sudo apt-get update 20 | sudo apt-get install -y libpq-dev 21 | - name: Bundle the Release 22 | id: bundle 23 | run: pgxn-bundle 24 | - name: Release on PGXN 25 | run: pgxn-release 26 | - name: Generate Release Changes 27 | run: make latest-changes.md 28 | - name: Create GitHub Release 29 | id: release 30 | uses: actions/create-release@v1 31 | with: 32 | tag_name: ${{ github.ref }} 33 | release_name: Release ${{ github.ref }} 34 | body_path: latest-changes.md 35 | - name: Upload Release Asset 36 | uses: actions/upload-release-asset@v1 37 | with: 38 | upload_url: ${{ steps.release.outputs.upload_url }} 39 | asset_path: ./${{ steps.bundle.outputs.bundle }} 40 | asset_name: ${{ steps.bundle.outputs.bundle }} 41 | asset_content_type: application/zip 42 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | .deps/ 2 | results/ 3 | **/*.o 4 | **/*.so 5 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright 2011, Tomas Vondra (tv@fuzzy.cz). All rights reserved. 2 | 3 | Redistribution and use in source and binary forms, with or without modification, are 4 | permitted provided that the following conditions are met: 5 | 6 | 1. Redistributions of source code must retain the above copyright notice, this list of 7 | conditions and the following disclaimer. 8 | 9 | 2. Redistributions in binary form must reproduce the above copyright notice, this list 10 | of conditions and the following disclaimer in the documentation and/or other materials 11 | provided with the distribution. 12 | 13 | THIS SOFTWARE IS PROVIDED BY TOMAS VONDRA ''AS IS'' AND ANY EXPRESS OR IMPLIED 14 | WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND 15 | FITNESS FOR A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL TOMAS VONDRA OR 16 | CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR 17 | CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 18 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON 19 | ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING 20 | NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF 21 | ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 22 | 23 | The views and conclusions contained in the software and documentation are those of the 24 | authors and should not be interpreted as representing official policies, either expressed 25 | or implied, of Tomas Vondra. -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "quantile", 3 | "abstract": "Aggregate for computing various quantiles (median, quartiles etc.) efficiently.", 4 | "description": "An extension written in C that allows you to evaluate various quantiles (with float and integer types) efficiently. It collects all the data in memory and allows you to compute multiple quantiles at the same time.", 5 | "version": "1.1.8", 6 | "maintainer": "Tomas Vondra ", 7 | "license": "bsd", 8 | "prereqs": { 9 | "runtime": { 10 | "requires": { 11 | "PostgreSQL": "8.4.0" 12 | } 13 | } 14 | }, 15 | "provides": { 16 | "quantile": { 17 | "file": "sql/quantile--1.1.8.sql", 18 | "docfile" : "README.md", 19 | "version": "1.1.8" 20 | } 21 | }, 22 | "resources": { 23 | "repository": { 24 | "url": "https://github.com/tvondra/quantile.git", 25 | "web": "http://github.com/tvondra/quantile", 26 | "type": "git" 27 | } 28 | }, 29 | "tags" : ["quantile", "median", "quartile", "aggregate"], 30 | "meta-spec": { 31 | "version": "1.0.0", 32 | "url": "http://pgxn.org/meta/spec.txt" 33 | }, 34 | "release_status" : "stable" 35 | } 36 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | MODULE_big = quantile 2 | OBJS = quantile.o 3 | 4 | EXTENSION = quantile 5 | DATA = sql/quantile--1.1.8.sql sql/quantile--1.1.4--1.1.5.sql sql/quantile--1.1.5--1.1.6.sql sql/quantile--1.1.6--1.1.7.sql sql/quantile--1.1.7--1.1.8.sql 6 | MODULES = quantile 7 | 8 | CFLAGS=`pg_config --includedir-server` 9 | 10 | TESTS = $(wildcard test/sql/*.sql) 11 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 12 | REGRESS_OPTS = --inputdir=test 13 | 14 | PG_CONFIG = pg_config 15 | PGXS := $(shell $(PG_CONFIG) --pgxs) 16 | include $(PGXS) 17 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Quantile aggregates 2 | 3 | [![make installcheck](https://github.com/tvondra/quantile/actions/workflows/ci.yml/badge.svg)](https://github.com/tvondra/quantile/actions/workflows/ci.yml) 4 | [![PGXN version](https://badge.fury.io/pg/quantile.svg)](https://badge.fury.io/pg/quantile) 5 | 6 | This extension provides three simple aggregate functions to compute 7 | quantiles (http://en.wikipedia.org/wiki/Quantile). There are two 8 | forms of aggregate functions available - the first one returns 9 | a single quantile, the second one returns an arbitrary number of 10 | quantiles (as an array). 11 | 12 | 13 | ## History 14 | 15 | This extension was created in 2011, before PostgreSQL added functions to 16 | compute percentiles (`percentile_cont` and `percentile_disc`) in 9.4, 17 | which was released in December 2014. Even after introduction of those 18 | built-in functions it made sense to use this extension, because it was 19 | significantly faster in various cases. 20 | 21 | The performance of the built-in functions improved a lot since then, and 22 | is usually very close or even faster than this extension. In some cases 23 | the extension is perhaps 2x faster than the built-in functions, but that 24 | may be (at least partially) attributed to not respecting `work_mem`. 25 | 26 | It's therefore recommended to evaluate the built-in functions first, and 27 | only use this extension if it's provably (and consistently) faster than 28 | the built-in functions and the risk of running out of memory is low, or 29 | when it's necessary to support older PostgreSQL releases (pre-9.4) that 30 | do not have the built-in alternatives. 31 | 32 | 33 | ## `quantile(p_value numeric, p_quantile float)` 34 | 35 | Computes arbitrary quantile of the values - the p_quantile has to be 36 | between 0 and 1. For example this should return 500 because 500 is the 37 | median of a sequence 1 .. 1000. 38 | 39 | ``` 40 | SELECT quantile(i, 0.5) FROM generate_series(1,1000) s(i); 41 | ``` 42 | 43 | but you can choose arbitrary quantile (for example 0.95). 44 | 45 | This function is overloaded for the four basic numeric types, i.e. 46 | `int`, `bigint`, `double precision` and `numeric`. 47 | 48 | 49 | ## `quantile(p_value numeric, p_quantiles float[])` 50 | 51 | If you need multiple quantiles at the same time (e.g. all four 52 | quartiles), you can use this function instead of the one described 53 | above. This version allows you to pass an array of quantiles and 54 | returns an array of values. 55 | 56 | So if you need all three quartiles, you may do this 57 | 58 | ``` 59 | SELECT quantile(i, ARRAY[0.25, 0.5, 0.75]) 60 | FROM generate_series(1,1000) s(i); 61 | ``` 62 | 63 | and it should return ARRAY[250, 500, 750]. Compared to calling 64 | the simple quantile function like this 65 | 66 | ``` 67 | SELECT quantile(i, 0.25), quantile(i, 0.5), quantile(i, 0.75) 68 | FROM generate_series(1,1000) s(i); 69 | ``` 70 | 71 | the advantage is that the values are collected just once (into 72 | a single array), not for each expression separately. If you're 73 | working with large data sets, this may save a significant amount 74 | of time and memory (if may even be the factor that allows the query 75 | to finish and not being killed by OOM killer or something). 76 | 77 | Just as in the first case, there are four functions handling other 78 | basic numeric types: `int`, `bigint`, `double precision` and `numeric`. 79 | 80 | 81 | ## Installation 82 | 83 | Installing this is very simple, especially if you're using pgxn client. 84 | All you need to do is this: 85 | 86 | $ pgxn install quantile 87 | $ pgxn load -d mydb quantile 88 | 89 | and you're done. You may also install the extension manually: 90 | 91 | $ make install 92 | $ psql dbname -c "CREATE EXTENSION quantile" 93 | 94 | And if you're on an older version (pre-9.1), you have to run the SQL 95 | script manually 96 | 97 | $ psql dbname < `pg_config --sharedir`/contrib/quantile--1.1.7.sql 98 | 99 | That's all. 100 | 101 | 102 | ## License 103 | 104 | This software is distributed under the terms of BSD 2-clause license. 105 | See LICENSE or http://www.opensource.org/licenses/bsd-license.php for 106 | more details. 107 | -------------------------------------------------------------------------------- /quantile.c: -------------------------------------------------------------------------------- 1 | /* 2 | * quantile.c - Quantile aggregate function 3 | * 4 | * Copyright (C) Tomas Vondra, 2011 5 | */ 6 | 7 | #include 8 | #include 9 | #include 10 | #include 11 | #include 12 | #include 13 | 14 | #include "postgres.h" 15 | #include "utils/array.h" 16 | #include "utils/lsyscache.h" 17 | #include "utils/numeric.h" 18 | #include "utils/builtins.h" 19 | #include "catalog/pg_type.h" 20 | #include "nodes/execnodes.h" 21 | 22 | #ifdef PG_MODULE_MAGIC 23 | PG_MODULE_MAGIC; 24 | #endif 25 | 26 | #if (PG_VERSION_NUM >= 90000) 27 | 28 | #define GET_AGG_CONTEXT(fname, fcinfo, aggcontext) \ 29 | if (! AggCheckCallContext(fcinfo, &aggcontext)) { \ 30 | elog(ERROR, "%s called in non-aggregate context", fname); \ 31 | } 32 | 33 | #define CHECK_AGG_CONTEXT(fname, fcinfo) \ 34 | if (! AggCheckCallContext(fcinfo, NULL)) { \ 35 | elog(ERROR, "%s called in non-aggregate context", fname); \ 36 | } 37 | 38 | #elif (PG_VERSION_NUM >= 80400) 39 | 40 | #define GET_AGG_CONTEXT(fname, fcinfo, aggcontext) \ 41 | if (fcinfo->context && IsA(fcinfo->context, AggState)) { \ 42 | aggcontext = ((AggState *) fcinfo->context)->aggcontext; \ 43 | } else if (fcinfo->context && IsA(fcinfo->context, WindowAggState)) { \ 44 | aggcontext = ((WindowAggState *) fcinfo->context)->wincontext; \ 45 | } else { \ 46 | elog(ERROR, "%s called in non-aggregate context", fname); \ 47 | aggcontext = NULL; \ 48 | } 49 | 50 | #define CHECK_AGG_CONTEXT(fname, fcinfo) \ 51 | if (!(fcinfo->context && \ 52 | (IsA(fcinfo->context, AggState) || \ 53 | IsA(fcinfo->context, WindowAggState)))) \ 54 | { \ 55 | elog(ERROR, "%s called in non-aggregate context", fname); \ 56 | } 57 | 58 | #else 59 | 60 | #define GET_AGG_CONTEXT(fname, fcinfo, aggcontext) \ 61 | if (fcinfo->context && IsA(fcinfo->context, AggState)) { \ 62 | aggcontext = ((AggState *) fcinfo->context)->aggcontext; \ 63 | } else { \ 64 | elog(ERROR, "%s called in non-aggregate context", fname); \ 65 | aggcontext = NULL; \ 66 | } 67 | 68 | #define CHECK_AGG_CONTEXT(fname, fcinfo) \ 69 | if (!(fcinfo->context && \ 70 | (IsA(fcinfo->context, AggState)))) \ 71 | { \ 72 | elog(ERROR, "%s called in non-aggregate context", fname); \ 73 | } 74 | 75 | #endif 76 | 77 | /* 78 | * Structures used to keep the data - the 'elements' array is extended 79 | * on the fly if needed. 80 | */ 81 | typedef struct quantile_state 82 | { 83 | int nquantiles; /* size of the quantiles array */ 84 | int maxelements; /* size of the elements array */ 85 | int nelements; /* number of elements */ 86 | 87 | /* arrays of elements and requested quantiles */ 88 | double *quantiles; 89 | void *elements; 90 | } quantile_state; 91 | 92 | #define QUANTILE_MIN_ELEMENTS 4 93 | 94 | /* comparators, used for qsort */ 95 | 96 | static int double_comparator(const void *a, const void *b); 97 | static int int32_comparator(const void *a, const void *b); 98 | static int int64_comparator(const void *a, const void *b); 99 | static int numeric_comparator(const void *a, const void *b); 100 | 101 | /* parse the quantiles array */ 102 | static double * 103 | array_to_double(FunctionCallInfo fcinfo, ArrayType *v, int * len); 104 | 105 | static Datum 106 | double_to_array(FunctionCallInfo fcinfo, double * d, int len); 107 | 108 | static Datum 109 | int32_to_array(FunctionCallInfo fcinfo, int32 * d, int len); 110 | 111 | static Datum 112 | int64_to_array(FunctionCallInfo fcinfo, int64 * d, int len); 113 | 114 | static Datum 115 | numeric_to_array(FunctionCallInfo fcinfo, Numeric * d, int len); 116 | 117 | static void 118 | check_quantiles(int nquantiles, double * quantiles); 119 | 120 | /* prototypes */ 121 | PG_FUNCTION_INFO_V1(quantile_append_double_array); 122 | PG_FUNCTION_INFO_V1(quantile_append_double); 123 | 124 | PG_FUNCTION_INFO_V1(quantile_double_array); 125 | PG_FUNCTION_INFO_V1(quantile_double); 126 | 127 | PG_FUNCTION_INFO_V1(quantile_append_int32_array); 128 | PG_FUNCTION_INFO_V1(quantile_append_int32); 129 | 130 | PG_FUNCTION_INFO_V1(quantile_int32_array); 131 | PG_FUNCTION_INFO_V1(quantile_int32); 132 | 133 | PG_FUNCTION_INFO_V1(quantile_append_int64_array); 134 | PG_FUNCTION_INFO_V1(quantile_append_int64); 135 | 136 | PG_FUNCTION_INFO_V1(quantile_int64_array); 137 | PG_FUNCTION_INFO_V1(quantile_int64); 138 | 139 | PG_FUNCTION_INFO_V1(quantile_append_numeric_array); 140 | PG_FUNCTION_INFO_V1(quantile_append_numeric); 141 | 142 | PG_FUNCTION_INFO_V1(quantile_numeric_array); 143 | PG_FUNCTION_INFO_V1(quantile_numeric); 144 | 145 | Datum quantile_append_double_array(PG_FUNCTION_ARGS); 146 | Datum quantile_append_double(PG_FUNCTION_ARGS); 147 | 148 | Datum quantile_double_array(PG_FUNCTION_ARGS); 149 | Datum quantile_double(PG_FUNCTION_ARGS); 150 | 151 | Datum quantile_append_int32_array(PG_FUNCTION_ARGS); 152 | Datum quantile_append_int32(PG_FUNCTION_ARGS); 153 | 154 | Datum quantile_int32_array(PG_FUNCTION_ARGS); 155 | Datum quantile_int32(PG_FUNCTION_ARGS); 156 | 157 | Datum quantile_append_int64_array(PG_FUNCTION_ARGS); 158 | Datum quantile_append_int64(PG_FUNCTION_ARGS); 159 | 160 | Datum quantile_int64_array(PG_FUNCTION_ARGS); 161 | Datum quantile_int64(PG_FUNCTION_ARGS); 162 | 163 | Datum quantile_append_numeric_array(PG_FUNCTION_ARGS); 164 | Datum quantile_append_numeric(PG_FUNCTION_ARGS); 165 | 166 | Datum quantile_numeric_array(PG_FUNCTION_ARGS); 167 | Datum quantile_numeric(PG_FUNCTION_ARGS); 168 | 169 | static void 170 | AssertCheckQuantileState(quantile_state *state) 171 | { 172 | #ifdef USE_ASSERT_CHECKING 173 | Assert(state->nquantiles >= 1); 174 | 175 | Assert(state->nelements >= 0); 176 | Assert(state->nelements <= state->maxelements); 177 | #endif 178 | } 179 | 180 | /* 181 | * The memory consumption might be a problem, as all the values are 182 | * kept in the memory - for example 1.000.000 of 8-byte values (bigint) 183 | * requires about 8MB of memory. 184 | */ 185 | 186 | Datum 187 | quantile_append_double(PG_FUNCTION_ARGS) 188 | { 189 | quantile_state *state; 190 | 191 | MemoryContext oldcontext; 192 | MemoryContext aggcontext; 193 | 194 | double *elements; 195 | 196 | /* OK, we do want to skip NULL values altogether */ 197 | if (PG_ARGISNULL(1)) 198 | { 199 | if (PG_ARGISNULL(0)) 200 | PG_RETURN_NULL(); 201 | else 202 | /* if there already is a state accumulated, don't forget it */ 203 | PG_RETURN_DATUM(PG_GETARG_DATUM(0)); 204 | } 205 | 206 | GET_AGG_CONTEXT("quantile_append_double", fcinfo, aggcontext); 207 | 208 | oldcontext = MemoryContextSwitchTo(aggcontext); 209 | 210 | if (PG_ARGISNULL(0)) 211 | { 212 | state = (quantile_state *) palloc(sizeof(quantile_state)); 213 | state->elements = palloc(QUANTILE_MIN_ELEMENTS * sizeof(double)); 214 | state->maxelements = QUANTILE_MIN_ELEMENTS; 215 | state->nelements = 0; 216 | 217 | state->quantiles = (double *) palloc(sizeof(double)); 218 | state->quantiles[0] = PG_GETARG_FLOAT8(2); 219 | state->nquantiles = 1; 220 | 221 | check_quantiles(state->nquantiles, state->quantiles); 222 | } 223 | else 224 | state = (quantile_state *) PG_GETARG_POINTER(0); 225 | 226 | AssertCheckQuantileState(state); 227 | 228 | /* we can be sure the value is not null (see the check above) */ 229 | if (state->nelements == state->maxelements) 230 | { 231 | state->maxelements *= 2; 232 | state->elements = repalloc(state->elements, 233 | sizeof(double) * state->maxelements); 234 | } 235 | 236 | Assert(state->nelements < state->maxelements); 237 | 238 | /* make sure to cast the array to (double *) before updating it */ 239 | elements = (double *) state->elements; 240 | elements[state->nelements++] = PG_GETARG_FLOAT8(1); 241 | 242 | MemoryContextSwitchTo(oldcontext); 243 | 244 | PG_RETURN_POINTER(state); 245 | } 246 | 247 | Datum 248 | quantile_append_double_array(PG_FUNCTION_ARGS) 249 | { 250 | quantile_state *state; 251 | 252 | MemoryContext oldcontext; 253 | MemoryContext aggcontext; 254 | 255 | double *elements; 256 | ArrayType *quantiles; 257 | 258 | /* OK, we do want to skip NULL values altogether */ 259 | if (PG_ARGISNULL(1)) 260 | { 261 | if (PG_ARGISNULL(0)) 262 | PG_RETURN_NULL(); 263 | else 264 | /* if there already is a state accumulated, don't forget it */ 265 | PG_RETURN_DATUM(PG_GETARG_DATUM(0)); 266 | } 267 | 268 | quantiles = PG_GETARG_ARRAYTYPE_P(2); 269 | 270 | GET_AGG_CONTEXT("quantile_append_double_array", fcinfo, aggcontext); 271 | 272 | oldcontext = MemoryContextSwitchTo(aggcontext); 273 | 274 | if (PG_ARGISNULL(0)) 275 | { 276 | state = (quantile_state *) palloc(sizeof(quantile_state)); 277 | state->elements = palloc(QUANTILE_MIN_ELEMENTS * sizeof(double)); 278 | state->maxelements = QUANTILE_MIN_ELEMENTS; 279 | state->nelements = 0; 280 | 281 | /* read the array of quantiles */ 282 | state->quantiles = array_to_double(fcinfo, quantiles, 283 | &state->nquantiles); 284 | 285 | check_quantiles(state->nquantiles, state->quantiles); 286 | } 287 | else 288 | state = (quantile_state *) PG_GETARG_POINTER(0); 289 | 290 | AssertCheckQuantileState(state); 291 | 292 | /* we can be sure the value is not null (see the check above) */ 293 | if (state->nelements == state->maxelements) 294 | { 295 | state->maxelements *= 2; 296 | state->elements = repalloc(state->elements, 297 | sizeof(double) * state->maxelements); 298 | } 299 | 300 | Assert(state->nelements < state->maxelements); 301 | 302 | elements = (double *) state->elements; 303 | elements[state->nelements++] = PG_GETARG_FLOAT8(1); 304 | 305 | MemoryContextSwitchTo(oldcontext); 306 | 307 | PG_RETURN_POINTER(state); 308 | } 309 | 310 | Datum 311 | quantile_append_numeric(PG_FUNCTION_ARGS) 312 | { 313 | quantile_state *state; 314 | 315 | MemoryContext oldcontext; 316 | MemoryContext aggcontext; 317 | 318 | Numeric num; 319 | Numeric value; 320 | Numeric *elements; 321 | 322 | /* OK, we do want to skip NULL values altogether */ 323 | if (PG_ARGISNULL(1)) 324 | { 325 | if (PG_ARGISNULL(0)) 326 | PG_RETURN_NULL(); 327 | else 328 | /* if there already is a state accumulated, don't forget it */ 329 | PG_RETURN_DATUM(PG_GETARG_DATUM(0)); 330 | } 331 | 332 | num = PG_GETARG_NUMERIC(1); 333 | 334 | GET_AGG_CONTEXT("quantile_append_numeric", fcinfo, aggcontext); 335 | 336 | oldcontext = MemoryContextSwitchTo(aggcontext); 337 | 338 | if (PG_ARGISNULL(0)) 339 | { 340 | state = (quantile_state *) palloc(sizeof(quantile_state)); 341 | state->elements = palloc(QUANTILE_MIN_ELEMENTS * sizeof(Numeric)); 342 | state->maxelements = QUANTILE_MIN_ELEMENTS; 343 | state->nelements = 0; 344 | 345 | state->quantiles = (double *) palloc(sizeof(double)); 346 | state->quantiles[0] = PG_GETARG_FLOAT8(2); 347 | state->nquantiles = 1; 348 | 349 | check_quantiles(state->nquantiles, state->quantiles); 350 | } 351 | else 352 | state = (quantile_state *) PG_GETARG_POINTER(0); 353 | 354 | AssertCheckQuantileState(state); 355 | 356 | /* we can be sure the value is not null (see the check above) */ 357 | if (state->nelements == state->maxelements) 358 | { 359 | state->maxelements *= 2; 360 | state->elements = repalloc(state->elements, 361 | sizeof(Numeric) * state->maxelements); 362 | } 363 | 364 | /* the value has to be copied into the right memory context */ 365 | value = (Numeric) palloc(VARSIZE(num)); 366 | memcpy(value, num, VARSIZE(num)); 367 | 368 | /* make sure to cast the array to (Numeric *) before updating it */ 369 | elements = (Numeric *) state->elements; 370 | elements[state->nelements++] = value; 371 | 372 | MemoryContextSwitchTo(oldcontext); 373 | 374 | PG_RETURN_POINTER(state); 375 | } 376 | 377 | Datum 378 | quantile_append_numeric_array(PG_FUNCTION_ARGS) 379 | { 380 | quantile_state *state; 381 | 382 | MemoryContext oldcontext; 383 | MemoryContext aggcontext; 384 | 385 | Numeric num; 386 | Numeric value; 387 | ArrayType *quantiles; 388 | Numeric *elements; 389 | 390 | /* OK, we do want to skip NULL values altogether */ 391 | if (PG_ARGISNULL(1)) 392 | { 393 | if (PG_ARGISNULL(0)) 394 | PG_RETURN_NULL(); 395 | else 396 | /* if there already is a state accumulated, don't forget it */ 397 | PG_RETURN_DATUM(PG_GETARG_DATUM(0)); 398 | } 399 | 400 | num = PG_GETARG_NUMERIC(1); 401 | quantiles = PG_GETARG_ARRAYTYPE_P(2); 402 | 403 | GET_AGG_CONTEXT("quantile_append_numeric_array", fcinfo, aggcontext); 404 | 405 | oldcontext = MemoryContextSwitchTo(aggcontext); 406 | 407 | if (PG_ARGISNULL(0)) 408 | { 409 | state = (quantile_state *) palloc(sizeof(quantile_state)); 410 | state->elements = palloc(QUANTILE_MIN_ELEMENTS * sizeof(Numeric)); 411 | state->maxelements = QUANTILE_MIN_ELEMENTS; 412 | state->nelements = 0; 413 | 414 | /* read the array of quantiles */ 415 | state->quantiles = array_to_double(fcinfo, quantiles, 416 | &state->nquantiles); 417 | 418 | check_quantiles(state->nquantiles, state->quantiles); 419 | } 420 | else 421 | state = (quantile_state *) PG_GETARG_POINTER(0); 422 | 423 | /* we can be sure the value is not null (see the check above) */ 424 | if (state->nelements == state->maxelements) 425 | { 426 | state->maxelements *= 2; 427 | state->elements = repalloc(state->elements, 428 | sizeof(Numeric) * state->maxelements); 429 | } 430 | 431 | /* the value has to be copied into the right memory context */ 432 | value = (Numeric) palloc(VARSIZE(num)); 433 | memcpy(value, num, VARSIZE(num)); 434 | 435 | /* make sure to cast the array to (Numeric *) before updating it */ 436 | elements = (Numeric *) state->elements; 437 | elements[state->nelements++] = value; 438 | 439 | MemoryContextSwitchTo(oldcontext); 440 | 441 | PG_RETURN_POINTER(state); 442 | } 443 | 444 | Datum 445 | quantile_append_int32(PG_FUNCTION_ARGS) 446 | { 447 | quantile_state *state; 448 | 449 | MemoryContext oldcontext; 450 | MemoryContext aggcontext; 451 | 452 | int32 *elements; 453 | 454 | /* OK, we do want to skip NULL values altogether */ 455 | if (PG_ARGISNULL(1)) 456 | { 457 | if (PG_ARGISNULL(0)) 458 | PG_RETURN_NULL(); 459 | else 460 | /* if there already is a state accumulated, don't forget it */ 461 | PG_RETURN_DATUM(PG_GETARG_DATUM(0)); 462 | } 463 | 464 | GET_AGG_CONTEXT("quantile_append_int32", fcinfo, aggcontext); 465 | 466 | oldcontext = MemoryContextSwitchTo(aggcontext); 467 | 468 | if (PG_ARGISNULL(0)) 469 | { 470 | state = (quantile_state *) palloc(sizeof(quantile_state)); 471 | 472 | state->elements = palloc(QUANTILE_MIN_ELEMENTS * sizeof(int32)); 473 | state->maxelements = QUANTILE_MIN_ELEMENTS; 474 | state->nelements = 0; 475 | 476 | state->quantiles = (double *) palloc(sizeof(double)); 477 | state->quantiles[0] = PG_GETARG_FLOAT8(2); 478 | state->nquantiles = 1; 479 | 480 | check_quantiles(state->nquantiles, state->quantiles); 481 | } 482 | else 483 | state = (quantile_state *) PG_GETARG_POINTER(0); 484 | 485 | AssertCheckQuantileState(state); 486 | 487 | /* we can be sure the value is not null (see the check above) */ 488 | if (state->nelements == state->maxelements) 489 | { 490 | state->maxelements *= 2; 491 | state->elements = repalloc(state->elements, 492 | sizeof(int32) * state->maxelements); 493 | } 494 | 495 | Assert(state->nelements < state->maxelements); 496 | 497 | /* make sure to cast the array to (int32 *) before updating it */ 498 | elements = (int32 *) state->elements; 499 | elements[state->nelements++] = PG_GETARG_INT32(1); 500 | 501 | MemoryContextSwitchTo(oldcontext); 502 | 503 | PG_RETURN_POINTER(state); 504 | } 505 | 506 | Datum 507 | quantile_append_int32_array(PG_FUNCTION_ARGS) 508 | { 509 | quantile_state *state; 510 | 511 | MemoryContext oldcontext; 512 | MemoryContext aggcontext; 513 | 514 | ArrayType *quantiles; 515 | int32 *elements; 516 | 517 | /* OK, we do want to skip NULL values altogether */ 518 | if (PG_ARGISNULL(1)) 519 | { 520 | if (PG_ARGISNULL(0)) 521 | PG_RETURN_NULL(); 522 | else 523 | /* if there already is a state accumulated, don't forget it */ 524 | PG_RETURN_DATUM(PG_GETARG_DATUM(0)); 525 | } 526 | 527 | quantiles = PG_GETARG_ARRAYTYPE_P(2); 528 | 529 | GET_AGG_CONTEXT("quantile_append_int32_array", fcinfo, aggcontext); 530 | 531 | oldcontext = MemoryContextSwitchTo(aggcontext); 532 | 533 | if (PG_ARGISNULL(0)) 534 | { 535 | state = (quantile_state *) palloc(sizeof(quantile_state)); 536 | 537 | state->elements = palloc(QUANTILE_MIN_ELEMENTS * sizeof(int32)); 538 | state->maxelements = QUANTILE_MIN_ELEMENTS; 539 | state->nelements = 0; 540 | 541 | /* read the array of quantiles */ 542 | state->quantiles = array_to_double(fcinfo, quantiles, 543 | &state->nquantiles); 544 | 545 | check_quantiles(state->nquantiles, state->quantiles); 546 | } 547 | else 548 | state = (quantile_state *) PG_GETARG_POINTER(0); 549 | 550 | AssertCheckQuantileState(state); 551 | 552 | /* we can be sure the value is not null (see the check above) */ 553 | if (state->nelements == state->maxelements) 554 | { 555 | state->maxelements *= 2; 556 | state->elements = repalloc(state->elements, 557 | sizeof(int32) * state->maxelements); 558 | } 559 | 560 | Assert(state->nelements < state->maxelements); 561 | 562 | /* make sure to cast the array to (int32 *) before updating it */ 563 | elements = (int32 *) state->elements; 564 | elements[state->nelements++] = PG_GETARG_INT32(1); 565 | 566 | MemoryContextSwitchTo(oldcontext); 567 | 568 | PG_RETURN_POINTER(state); 569 | } 570 | 571 | Datum 572 | quantile_append_int64(PG_FUNCTION_ARGS) 573 | { 574 | quantile_state *state; 575 | 576 | MemoryContext oldcontext; 577 | MemoryContext aggcontext; 578 | 579 | int64 *elements; 580 | 581 | /* OK, we do want to skip NULL values altogether */ 582 | if (PG_ARGISNULL(1)) 583 | { 584 | if (PG_ARGISNULL(0)) 585 | PG_RETURN_NULL(); 586 | else 587 | /* if there already is a state accumulated, don't forget it */ 588 | PG_RETURN_DATUM(PG_GETARG_DATUM(0)); 589 | } 590 | 591 | GET_AGG_CONTEXT("quantile_append_int64", fcinfo, aggcontext); 592 | 593 | oldcontext = MemoryContextSwitchTo(aggcontext); 594 | 595 | if (PG_ARGISNULL(0)) 596 | { 597 | state = (quantile_state *) palloc(sizeof(quantile_state)); 598 | 599 | state->elements = palloc(QUANTILE_MIN_ELEMENTS * sizeof(int64)); 600 | state->maxelements = QUANTILE_MIN_ELEMENTS; 601 | state->nelements = 0; 602 | 603 | state->quantiles = (double *) palloc(sizeof(double)); 604 | state->quantiles[0] = PG_GETARG_FLOAT8(2); 605 | state->nquantiles = 1; 606 | 607 | check_quantiles(state->nquantiles, state->quantiles); 608 | } 609 | else 610 | state = (quantile_state *) PG_GETARG_POINTER(0); 611 | 612 | AssertCheckQuantileState(state); 613 | 614 | /* we can be sure the value is not null (see the check above) */ 615 | if (state->nelements == state->maxelements) 616 | { 617 | state->maxelements *= 2; 618 | state->elements = repalloc(state->elements, 619 | sizeof(int64) * state->maxelements); 620 | } 621 | 622 | Assert(state->nelements < state->maxelements); 623 | 624 | /* make sure to cast the array to (int64 *) before updating it */ 625 | elements = (int64 *) state->elements; 626 | elements[state->nelements++] = PG_GETARG_INT64(1); 627 | 628 | MemoryContextSwitchTo(oldcontext); 629 | 630 | PG_RETURN_POINTER(state); 631 | } 632 | 633 | Datum 634 | quantile_append_int64_array(PG_FUNCTION_ARGS) 635 | { 636 | quantile_state *state; 637 | 638 | MemoryContext oldcontext; 639 | MemoryContext aggcontext; 640 | 641 | ArrayType *quantiles; 642 | int64 *elements; 643 | 644 | /* OK, we do want to skip NULL values altogether */ 645 | if (PG_ARGISNULL(1)) 646 | { 647 | if (PG_ARGISNULL(0)) 648 | PG_RETURN_NULL(); 649 | else 650 | /* if there already is a state accumulated, don't forget it */ 651 | PG_RETURN_DATUM(PG_GETARG_DATUM(0)); 652 | } 653 | 654 | quantiles = PG_GETARG_ARRAYTYPE_P(2); 655 | 656 | GET_AGG_CONTEXT("quantile_append_int64_array", fcinfo, aggcontext); 657 | 658 | oldcontext = MemoryContextSwitchTo(aggcontext); 659 | 660 | if (PG_ARGISNULL(0)) 661 | { 662 | state = (quantile_state *) palloc(sizeof(quantile_state)); 663 | state->elements = palloc(QUANTILE_MIN_ELEMENTS * sizeof(int64)); 664 | state->maxelements = QUANTILE_MIN_ELEMENTS; 665 | state->nelements = 0; 666 | 667 | /* read the array of quantiles */ 668 | state->quantiles = array_to_double(fcinfo, quantiles, 669 | &state->nquantiles); 670 | 671 | check_quantiles(state->nquantiles, state->quantiles); 672 | } 673 | else 674 | state = (quantile_state *) PG_GETARG_POINTER(0); 675 | 676 | AssertCheckQuantileState(state); 677 | 678 | /* we can be sure the value is not null (see the check above) */ 679 | if (state->nelements == state->maxelements) 680 | { 681 | state->maxelements *= 2; 682 | state->elements = repalloc(state->elements, 683 | sizeof(int64) * state->maxelements); 684 | } 685 | 686 | Assert(state->nelements < state->maxelements); 687 | 688 | /* make sure to cast the array to (int64 *) before updating it */ 689 | elements = (int64 *) state->elements; 690 | elements[state->nelements++] = PG_GETARG_INT64(1); 691 | 692 | MemoryContextSwitchTo(oldcontext); 693 | 694 | PG_RETURN_POINTER(state); 695 | } 696 | 697 | Datum 698 | quantile_double(PG_FUNCTION_ARGS) 699 | { 700 | int idx = 0; 701 | quantile_state *state; 702 | double *elements; 703 | 704 | CHECK_AGG_CONTEXT("quantile_double", fcinfo); 705 | 706 | if (PG_ARGISNULL(0)) 707 | PG_RETURN_NULL(); 708 | 709 | state = (quantile_state *) PG_GETARG_POINTER(0); 710 | elements = (double *) state->elements; 711 | 712 | qsort(state->elements, state->nelements, sizeof(double), &double_comparator); 713 | 714 | if (state->quantiles[0] > 0) 715 | idx = (int) ceil(state->nelements * state->quantiles[0]) - 1; 716 | 717 | PG_RETURN_FLOAT8(elements[idx]); 718 | } 719 | 720 | Datum 721 | quantile_double_array(PG_FUNCTION_ARGS) 722 | { 723 | int i; 724 | double *result; 725 | quantile_state *state; 726 | double *elements; 727 | 728 | CHECK_AGG_CONTEXT("quantile_double_array", fcinfo); 729 | 730 | if (PG_ARGISNULL(0)) 731 | PG_RETURN_NULL(); 732 | 733 | state = (quantile_state *) PG_GETARG_POINTER(0); 734 | 735 | result = palloc(state->nquantiles * sizeof(double)); 736 | elements = (double *) state->elements; 737 | 738 | qsort(state->elements, state->nelements, sizeof(double), &double_comparator); 739 | 740 | for (i = 0; i < state->nquantiles; i++) 741 | { 742 | int idx = 0; 743 | 744 | if (state->quantiles[i] > 0) 745 | idx = (int) ceil(state->nelements * state->quantiles[i]) - 1; 746 | 747 | result[i] = elements[idx]; 748 | } 749 | 750 | return double_to_array(fcinfo, result, state->nquantiles); 751 | } 752 | 753 | Datum 754 | quantile_int32(PG_FUNCTION_ARGS) 755 | { 756 | int idx = 0; 757 | quantile_state *state; 758 | int32 *elements; 759 | 760 | CHECK_AGG_CONTEXT("quantile_int32", fcinfo); 761 | 762 | if (PG_ARGISNULL(0)) 763 | PG_RETURN_NULL(); 764 | 765 | state = (quantile_state *) PG_GETARG_POINTER(0); 766 | elements = (int32 *) state->elements; 767 | 768 | qsort(state->elements, state->nelements, sizeof(int32), &int32_comparator); 769 | 770 | if (state->quantiles[0] > 0) 771 | idx = (int) ceil(state->nelements * state->quantiles[0]) - 1; 772 | 773 | PG_RETURN_INT32(elements[idx]); 774 | } 775 | 776 | Datum 777 | quantile_int32_array(PG_FUNCTION_ARGS) 778 | { 779 | int i; 780 | quantile_state *state; 781 | int32 *result; 782 | int32 *elements; 783 | 784 | CHECK_AGG_CONTEXT("quantile_int32_array", fcinfo); 785 | 786 | if (PG_ARGISNULL(0)) 787 | PG_RETURN_NULL(); 788 | 789 | state = (quantile_state *) PG_GETARG_POINTER(0); 790 | 791 | result = palloc(state->nquantiles * sizeof(int32)); 792 | elements = (int32 *) state->elements; 793 | 794 | qsort(state->elements, state->nelements, sizeof(int32), &int32_comparator); 795 | 796 | for (i = 0; i < state->nquantiles; i++) 797 | { 798 | int idx = 0; 799 | if (state->quantiles[i] > 0) 800 | idx = (int) ceil(state->nelements * state->quantiles[i]) - 1; 801 | 802 | result[i] = elements[idx]; 803 | } 804 | 805 | return int32_to_array(fcinfo, result, state->nquantiles); 806 | } 807 | 808 | Datum 809 | quantile_int64(PG_FUNCTION_ARGS) 810 | { 811 | int idx = 0; 812 | quantile_state *state; 813 | int64 *elements; 814 | 815 | CHECK_AGG_CONTEXT("quantile_int64", fcinfo); 816 | 817 | if (PG_ARGISNULL(0)) 818 | PG_RETURN_NULL(); 819 | 820 | state = (quantile_state *) PG_GETARG_POINTER(0); 821 | 822 | elements = (int64 *) state->elements; 823 | 824 | qsort(state->elements, state->nelements, sizeof(int64), &int64_comparator); 825 | 826 | if (state->quantiles[0] > 0) 827 | idx = (int) ceil(state->nelements * state->quantiles[0]) - 1; 828 | 829 | PG_RETURN_INT64(elements[idx]); 830 | } 831 | 832 | Datum 833 | quantile_int64_array(PG_FUNCTION_ARGS) 834 | { 835 | int i; 836 | quantile_state *state; 837 | int64 *result; 838 | int64 *elements; 839 | 840 | CHECK_AGG_CONTEXT("quantile_int64_array", fcinfo); 841 | 842 | if (PG_ARGISNULL(0)) 843 | PG_RETURN_NULL(); 844 | 845 | state = (quantile_state *) PG_GETARG_POINTER(0); 846 | 847 | elements = (int64 *) state->elements; 848 | 849 | result = palloc(state->nquantiles * sizeof(int64)); 850 | 851 | qsort(state->elements, state->nelements, sizeof(int64), &int64_comparator); 852 | 853 | for (i = 0; i < state->nquantiles; i++) 854 | { 855 | int idx = 0; 856 | if (state->quantiles[i] > 0) 857 | idx = (int) ceil(state->nelements * state->quantiles[i]) - 1; 858 | 859 | result[i] = elements[idx]; 860 | } 861 | 862 | return int64_to_array(fcinfo, result, state->nquantiles); 863 | } 864 | 865 | Datum 866 | quantile_numeric(PG_FUNCTION_ARGS) 867 | { 868 | int idx = 0; 869 | quantile_state *state; 870 | Numeric *elements; 871 | 872 | CHECK_AGG_CONTEXT("quantile_numeric", fcinfo); 873 | 874 | if (PG_ARGISNULL(0)) 875 | PG_RETURN_NULL(); 876 | 877 | state = (quantile_state *) PG_GETARG_POINTER(0); 878 | 879 | elements = (Numeric *) state->elements; 880 | 881 | qsort(state->elements, state->nelements, sizeof(Numeric), &numeric_comparator); 882 | 883 | if (state->quantiles[0] > 0) 884 | idx = (int) ceil(state->nelements * state->quantiles[0]) - 1; 885 | 886 | PG_RETURN_NUMERIC(elements[idx]); 887 | } 888 | 889 | Datum 890 | quantile_numeric_array(PG_FUNCTION_ARGS) 891 | { 892 | int i; 893 | quantile_state *state; 894 | Numeric *result; 895 | Numeric *elements; 896 | 897 | CHECK_AGG_CONTEXT("quantile_numeric_array", fcinfo); 898 | 899 | if (PG_ARGISNULL(0)) 900 | PG_RETURN_NULL(); 901 | 902 | state = (quantile_state *) PG_GETARG_POINTER(0); 903 | 904 | elements = (Numeric *) state->elements; 905 | 906 | result = palloc(state->nquantiles * sizeof(Numeric)); 907 | 908 | elements = (Numeric *) state->elements; 909 | 910 | qsort(elements, state->nelements, sizeof(Numeric), &numeric_comparator); 911 | 912 | for (i = 0; i < state->nquantiles; i++) 913 | { 914 | int idx = 0; 915 | 916 | if (state->quantiles[i] > 0) 917 | idx = (int) ceil(state->nelements * state->quantiles[i]) - 1; 918 | 919 | result[i] = elements[idx]; 920 | } 921 | 922 | return numeric_to_array(fcinfo, result, state->nquantiles); 923 | } 924 | 925 | /* Comparators for the qsort() calls. */ 926 | 927 | static int 928 | double_comparator(const void *a, const void *b) 929 | { 930 | double af = (* (double*) a); 931 | double bf = (* (double*) b); 932 | return (af > bf) - (af < bf); 933 | } 934 | 935 | static int 936 | int32_comparator(const void *a, const void *b) 937 | { 938 | int32 af = (* (int32 *) a); 939 | int32 bf = (* (int32 *) b); 940 | return (af > bf) - (af < bf); 941 | } 942 | 943 | static int 944 | int64_comparator(const void *a, const void *b) 945 | { 946 | int64 af = (* (int64 *) a); 947 | int64 bf = (* (int64 *) b); 948 | return (af > bf) - (af < bf); 949 | } 950 | 951 | static int 952 | numeric_comparator(const void *a, const void *b) 953 | { 954 | Numeric na = (* (Numeric *) a); 955 | Numeric nb = (* (Numeric *) b); 956 | 957 | return DatumGetInt32(DirectFunctionCall2(numeric_cmp, 958 | NumericGetDatum(na), 959 | NumericGetDatum(nb))); 960 | } 961 | 962 | /* 963 | * Reading quantiles from an input array, based mostly on 964 | * array_to_text_internal (it's a modified copy). This expects 965 | * to receive a single-dimensional float8 array as input, fails 966 | * otherwise. 967 | */ 968 | static double * 969 | array_to_double(FunctionCallInfo fcinfo, ArrayType *array, int *arraylen) 970 | { 971 | int i; 972 | Datum *keys; 973 | int nkeys; 974 | 975 | /* info for deconstructing the array */ 976 | Oid element_type; 977 | int typlen; 978 | bool typbyval; 979 | char typalign; 980 | 981 | ArrayMetaState *my_extra; 982 | 983 | /* result */ 984 | double *result; 985 | 986 | element_type = ARR_ELEMTYPE(array); 987 | 988 | if (element_type != FLOAT8OID) 989 | elog(ERROR, "array expected to be double precision[]"); 990 | 991 | /* 992 | * We arrange to look up info about element type, including its output 993 | * conversion proc, only once per series of calls, assuming the element 994 | * type doesn't change underneath us. 995 | */ 996 | my_extra = (ArrayMetaState *) fcinfo->flinfo->fn_extra; 997 | if (my_extra == NULL) 998 | { 999 | fcinfo->flinfo->fn_extra = MemoryContextAlloc(fcinfo->flinfo->fn_mcxt, 1000 | sizeof(ArrayMetaState)); 1001 | my_extra = (ArrayMetaState *) fcinfo->flinfo->fn_extra; 1002 | my_extra->element_type = ~element_type; 1003 | } 1004 | 1005 | /* 1006 | * Get info about element type, including its output conversion proc, if 1007 | * we haven't done that already. 1008 | */ 1009 | if (my_extra->element_type != element_type) 1010 | { 1011 | get_type_io_data(element_type, IOFunc_output, 1012 | &my_extra->typlen, &my_extra->typbyval, 1013 | &my_extra->typalign, &my_extra->typdelim, 1014 | &my_extra->typioparam, &my_extra->typiofunc); 1015 | fmgr_info_cxt(my_extra->typiofunc, &my_extra->proc, 1016 | fcinfo->flinfo->fn_mcxt); 1017 | my_extra->element_type = element_type; 1018 | } 1019 | 1020 | typlen = my_extra->typlen; 1021 | typbyval = my_extra->typbyval; 1022 | typalign = my_extra->typalign; 1023 | 1024 | /* Extract data from array of int16 */ 1025 | deconstruct_array(array, FLOAT8OID, typlen, typbyval, typalign, 1026 | &keys, NULL, &nkeys); 1027 | 1028 | result = (double *) palloc(sizeof(double) * nkeys); 1029 | 1030 | for (i = 0; i < nkeys; i++) 1031 | result[i] = DatumGetFloat8(keys[i]); 1032 | 1033 | *arraylen = nkeys; 1034 | 1035 | return result; 1036 | } 1037 | 1038 | /* 1039 | * Helper functions used to prepare the resulting array (when there's 1040 | * an array of quantiles). 1041 | */ 1042 | static Datum 1043 | double_to_array(FunctionCallInfo fcinfo, double * d, int len) 1044 | { 1045 | ArrayBuildState *astate = NULL; 1046 | int i; 1047 | 1048 | for (i = 0; i < len; i++) 1049 | { 1050 | /* stash away this field */ 1051 | astate = accumArrayResult(astate, 1052 | Float8GetDatum(d[i]), 1053 | false, 1054 | FLOAT8OID, 1055 | CurrentMemoryContext); 1056 | } 1057 | 1058 | PG_RETURN_DATUM(makeArrayResult(astate, 1059 | CurrentMemoryContext)); 1060 | } 1061 | 1062 | static Datum 1063 | int32_to_array(FunctionCallInfo fcinfo, int32 * d, int len) 1064 | { 1065 | ArrayBuildState *astate = NULL; 1066 | int i; 1067 | 1068 | for (i = 0; i < len; i++) 1069 | { 1070 | /* stash away this field */ 1071 | astate = accumArrayResult(astate, 1072 | Int32GetDatum(d[i]), 1073 | false, 1074 | INT4OID, 1075 | CurrentMemoryContext); 1076 | } 1077 | 1078 | PG_RETURN_DATUM(makeArrayResult(astate, 1079 | CurrentMemoryContext)); 1080 | } 1081 | 1082 | static Datum 1083 | int64_to_array(FunctionCallInfo fcinfo, int64 * d, int len) 1084 | { 1085 | 1086 | ArrayBuildState *astate = NULL; 1087 | int i; 1088 | 1089 | for (i = 0; i < len; i++) 1090 | { 1091 | /* stash away this field */ 1092 | astate = accumArrayResult(astate, 1093 | Int64GetDatum(d[i]), 1094 | false, 1095 | INT8OID, 1096 | CurrentMemoryContext); 1097 | } 1098 | 1099 | PG_RETURN_DATUM(makeArrayResult(astate, 1100 | CurrentMemoryContext)); 1101 | } 1102 | 1103 | static Datum 1104 | numeric_to_array(FunctionCallInfo fcinfo, Numeric * d, int len) 1105 | { 1106 | ArrayBuildState *astate = NULL; 1107 | int i; 1108 | 1109 | for (i = 0; i < len; i++) 1110 | { 1111 | /* stash away this field */ 1112 | astate = accumArrayResult(astate, 1113 | NumericGetDatum(d[i]), 1114 | false, 1115 | NUMERICOID, 1116 | CurrentMemoryContext); 1117 | } 1118 | 1119 | PG_RETURN_DATUM(makeArrayResult(astate, 1120 | CurrentMemoryContext)); 1121 | } 1122 | 1123 | static void 1124 | check_quantiles(int nquantiles, double * quantiles) 1125 | { 1126 | int i = 0; 1127 | for (i = 0; i < nquantiles; i++) 1128 | if (quantiles[i] < 0 || quantiles[i] > 1) 1129 | elog(ERROR, "invalid percentile value %f - needs to be in [0,1]", quantiles[i]); 1130 | } 1131 | -------------------------------------------------------------------------------- /quantile.control: -------------------------------------------------------------------------------- 1 | # quantile aggregate 2 | comment = 'Provides quantile aggregate function.' 3 | default_version = '1.1.8' 4 | relocatable = true 5 | -------------------------------------------------------------------------------- /sql/quantile--1.1.4--1.1.5.sql: -------------------------------------------------------------------------------- 1 | -- empty 2 | -------------------------------------------------------------------------------- /sql/quantile--1.1.5--1.1.6.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tvondra/quantile/83ce53d3c985d82cf18795e5a4b4a15cb140f922/sql/quantile--1.1.5--1.1.6.sql -------------------------------------------------------------------------------- /sql/quantile--1.1.6--1.1.7.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tvondra/quantile/83ce53d3c985d82cf18795e5a4b4a15cb140f922/sql/quantile--1.1.6--1.1.7.sql -------------------------------------------------------------------------------- /sql/quantile--1.1.7--1.1.8.sql: -------------------------------------------------------------------------------- 1 | 2 | -------------------------------------------------------------------------------- /sql/quantile--1.1.8.sql: -------------------------------------------------------------------------------- 1 | /* quantile for the double precision */ 2 | CREATE OR REPLACE FUNCTION quantile_append_double(p_pointer internal, p_element double precision, p_quantile double precision) 3 | RETURNS internal 4 | AS 'quantile', 'quantile_append_double' 5 | LANGUAGE C IMMUTABLE; 6 | 7 | CREATE OR REPLACE FUNCTION quantile_append_double_array(p_pointer internal, p_element double precision, p_quantiles double precision[]) 8 | RETURNS internal 9 | AS 'quantile', 'quantile_append_double_array' 10 | LANGUAGE C IMMUTABLE; 11 | 12 | CREATE OR REPLACE FUNCTION quantile_double(p_pointer internal) 13 | RETURNS double precision 14 | AS 'quantile', 'quantile_double' 15 | LANGUAGE C IMMUTABLE; 16 | 17 | CREATE OR REPLACE FUNCTION quantile_double_array(p_pointer internal) 18 | RETURNS double precision[] 19 | AS 'quantile', 'quantile_double_array' 20 | LANGUAGE C IMMUTABLE; 21 | 22 | CREATE AGGREGATE quantile(double precision, double precision) ( 23 | SFUNC = quantile_append_double, 24 | STYPE = internal, 25 | FINALFUNC = quantile_double 26 | ); 27 | 28 | CREATE AGGREGATE quantile(double precision, double precision[]) ( 29 | SFUNC = quantile_append_double_array, 30 | STYPE = internal, 31 | FINALFUNC = quantile_double_array 32 | ); 33 | 34 | /* quantile for the numeric */ 35 | CREATE OR REPLACE FUNCTION quantile_append_numeric(p_pointer internal, p_element numeric, p_quantiles double precision) 36 | RETURNS internal 37 | AS 'quantile', 'quantile_append_numeric' 38 | LANGUAGE C IMMUTABLE; 39 | 40 | CREATE OR REPLACE FUNCTION quantile_append_numeric_array(p_pointer internal, p_element numeric, p_quantiles double precision[]) 41 | RETURNS internal 42 | AS 'quantile', 'quantile_append_numeric_array' 43 | LANGUAGE C IMMUTABLE; 44 | 45 | CREATE OR REPLACE FUNCTION quantile_numeric(p_pointer internal) 46 | RETURNS numeric 47 | AS 'quantile', 'quantile_numeric' 48 | LANGUAGE C IMMUTABLE; 49 | 50 | CREATE OR REPLACE FUNCTION quantile_numeric_array(p_pointer internal) 51 | RETURNS numeric[] 52 | AS 'quantile', 'quantile_numeric_array' 53 | LANGUAGE C IMMUTABLE; 54 | 55 | CREATE AGGREGATE quantile(numeric, double precision) ( 56 | SFUNC = quantile_append_numeric, 57 | STYPE = internal, 58 | FINALFUNC = quantile_numeric 59 | ); 60 | 61 | CREATE AGGREGATE quantile(numeric, double precision[]) ( 62 | SFUNC = quantile_append_numeric_array, 63 | STYPE = internal, 64 | FINALFUNC = quantile_numeric_array 65 | ); 66 | 67 | /* quantile for the int32 */ 68 | CREATE OR REPLACE FUNCTION quantile_append_int32(p_pointer internal, p_element int, p_quantile double precision) 69 | RETURNS internal 70 | AS 'quantile', 'quantile_append_int32' 71 | LANGUAGE C IMMUTABLE; 72 | 73 | CREATE OR REPLACE FUNCTION quantile_append_int32_array(p_pointer internal, p_element int, p_quantiles double precision[]) 74 | RETURNS internal 75 | AS 'quantile', 'quantile_append_int32_array' 76 | LANGUAGE C IMMUTABLE; 77 | 78 | CREATE OR REPLACE FUNCTION quantile_int32(p_pointer internal) 79 | RETURNS int 80 | AS 'quantile', 'quantile_int32' 81 | LANGUAGE C IMMUTABLE; 82 | 83 | CREATE OR REPLACE FUNCTION quantile_int32_array(p_pointer internal) 84 | RETURNS int[] 85 | AS 'quantile', 'quantile_int32_array' 86 | LANGUAGE C IMMUTABLE; 87 | 88 | CREATE AGGREGATE quantile(int, double precision) ( 89 | SFUNC = quantile_append_int32, 90 | STYPE = internal, 91 | FINALFUNC = quantile_int32 92 | ); 93 | 94 | CREATE AGGREGATE quantile(int, double precision[]) ( 95 | SFUNC = quantile_append_int32_array, 96 | STYPE = internal, 97 | FINALFUNC = quantile_int32_array 98 | ); 99 | 100 | /* quantile for the int64 */ 101 | CREATE OR REPLACE FUNCTION quantile_append_int64(p_pointer internal, p_element bigint, p_quantile double precision) 102 | RETURNS internal 103 | AS 'quantile', 'quantile_append_int64' 104 | LANGUAGE C IMMUTABLE; 105 | 106 | CREATE OR REPLACE FUNCTION quantile_append_int64_array(p_pointer internal, p_element bigint, p_quantiles double precision[]) 107 | RETURNS internal 108 | AS 'quantile', 'quantile_append_int64_array' 109 | LANGUAGE C IMMUTABLE; 110 | 111 | CREATE OR REPLACE FUNCTION quantile_int64(p_pointer internal) 112 | RETURNS bigint 113 | AS 'quantile', 'quantile_int64' 114 | LANGUAGE C IMMUTABLE; 115 | 116 | CREATE OR REPLACE FUNCTION quantile_int64_array(p_pointer internal) 117 | RETURNS bigint[] 118 | AS 'quantile', 'quantile_int64_array' 119 | LANGUAGE C IMMUTABLE; 120 | 121 | /* actual aggregates */ 122 | 123 | CREATE AGGREGATE quantile(bigint, double precision) ( 124 | SFUNC = quantile_append_int64, 125 | STYPE = internal, 126 | FINALFUNC = quantile_int64 127 | ); 128 | 129 | CREATE AGGREGATE quantile(bigint, double precision[]) ( 130 | SFUNC = quantile_append_int64_array, 131 | STYPE = internal, 132 | FINALFUNC = quantile_int64_array 133 | ); 134 | -------------------------------------------------------------------------------- /test/expected/base.out: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | -- int 3 | SELECT quantile(x, -0.5) FROM generate_series(1,1000) s(x); 4 | ERROR: invalid percentile value -0.500000 - needs to be in [0,1] 5 | SELECT quantile(x, 1.5) FROM generate_series(1,1000) s(x); 6 | ERROR: invalid percentile value 1.500000 - needs to be in [0,1] 7 | SELECT quantile(x, 0.5) FROM generate_series(1,1000) s(x); 8 | quantile 9 | ---------- 10 | 500 11 | (1 row) 12 | 13 | SELECT quantile(x, 0.1) FROM generate_series(1,1000) s(x); 14 | quantile 15 | ---------- 16 | 100 17 | (1 row) 18 | 19 | SELECT quantile(x, 0) FROM generate_series(1,1000) s(x); 20 | quantile 21 | ---------- 22 | 1 23 | (1 row) 24 | 25 | SELECT quantile(x, 1) FROM generate_series(1,1000) s(x); 26 | quantile 27 | ---------- 28 | 1000 29 | (1 row) 30 | 31 | SELECT quantile(x, ARRAY[0.5]) FROM generate_series(1,1000) s(x); 32 | quantile 33 | ---------- 34 | {500} 35 | (1 row) 36 | 37 | SELECT quantile(x, ARRAY[0.1]) FROM generate_series(1,1000) s(x); 38 | quantile 39 | ---------- 40 | {100} 41 | (1 row) 42 | 43 | SELECT quantile(x, ARRAY[0]) FROM generate_series(1,1000) s(x); 44 | quantile 45 | ---------- 46 | {1} 47 | (1 row) 48 | 49 | SELECT quantile(x, ARRAY[1]) FROM generate_series(1,1000) s(x); 50 | quantile 51 | ---------- 52 | {1000} 53 | (1 row) 54 | 55 | SELECT quantile(x, ARRAY[0, 0.1, 0.5, 0.75, 1]) FROM generate_series(1,1000) s(x); 56 | quantile 57 | ---------------------- 58 | {1,100,500,750,1000} 59 | (1 row) 60 | 61 | -- bigint 62 | SELECT quantile(x::bigint, -0.5) FROM generate_series(1,1000) s(x); 63 | ERROR: invalid percentile value -0.500000 - needs to be in [0,1] 64 | SELECT quantile(x::bigint, 1.5) FROM generate_series(1,1000) s(x); 65 | ERROR: invalid percentile value 1.500000 - needs to be in [0,1] 66 | SELECT quantile(x::bigint, 0.5) FROM generate_series(1,1000) s(x); 67 | quantile 68 | ---------- 69 | 500 70 | (1 row) 71 | 72 | SELECT quantile(x::bigint, 0.1) FROM generate_series(1,1000) s(x); 73 | quantile 74 | ---------- 75 | 100 76 | (1 row) 77 | 78 | SELECT quantile(x::bigint, 0) FROM generate_series(1,1000) s(x); 79 | quantile 80 | ---------- 81 | 1 82 | (1 row) 83 | 84 | SELECT quantile(x::bigint, 1) FROM generate_series(1,1000) s(x); 85 | quantile 86 | ---------- 87 | 1000 88 | (1 row) 89 | 90 | SELECT quantile(x::bigint, ARRAY[0.5]) FROM generate_series(1,1000) s(x); 91 | quantile 92 | ---------- 93 | {500} 94 | (1 row) 95 | 96 | SELECT quantile(x::bigint, ARRAY[0.1]) FROM generate_series(1,1000) s(x); 97 | quantile 98 | ---------- 99 | {100} 100 | (1 row) 101 | 102 | SELECT quantile(x::bigint, ARRAY[0]) FROM generate_series(1,1000) s(x); 103 | quantile 104 | ---------- 105 | {1} 106 | (1 row) 107 | 108 | SELECT quantile(x::bigint, ARRAY[1]) FROM generate_series(1,1000) s(x); 109 | quantile 110 | ---------- 111 | {1000} 112 | (1 row) 113 | 114 | SELECT quantile(x::bigint, ARRAY[0, 0.1, 0.5, 0.75, 1]) FROM generate_series(1,1000) s(x); 115 | quantile 116 | ---------------------- 117 | {1,100,500,750,1000} 118 | (1 row) 119 | 120 | -- double precision 121 | SELECT quantile(x::double precision, -0.5) FROM generate_series(1,1000) s(x); 122 | ERROR: invalid percentile value -0.500000 - needs to be in [0,1] 123 | SELECT quantile(x::double precision, 1.5) FROM generate_series(1,1000) s(x); 124 | ERROR: invalid percentile value 1.500000 - needs to be in [0,1] 125 | SELECT quantile(x::double precision, 0.5) FROM generate_series(1,1000) s(x); 126 | quantile 127 | ---------- 128 | 500 129 | (1 row) 130 | 131 | SELECT quantile(x::double precision, 0.1) FROM generate_series(1,1000) s(x); 132 | quantile 133 | ---------- 134 | 100 135 | (1 row) 136 | 137 | SELECT quantile(x::double precision, 0) FROM generate_series(1,1000) s(x); 138 | quantile 139 | ---------- 140 | 1 141 | (1 row) 142 | 143 | SELECT quantile(x::double precision, 1) FROM generate_series(1,1000) s(x); 144 | quantile 145 | ---------- 146 | 1000 147 | (1 row) 148 | 149 | SELECT quantile(x::double precision, ARRAY[0.5]) FROM generate_series(1,1000) s(x); 150 | quantile 151 | ---------- 152 | {500} 153 | (1 row) 154 | 155 | SELECT quantile(x::double precision, ARRAY[0.1]) FROM generate_series(1,1000) s(x); 156 | quantile 157 | ---------- 158 | {100} 159 | (1 row) 160 | 161 | SELECT quantile(x::double precision, ARRAY[0]) FROM generate_series(1,1000) s(x); 162 | quantile 163 | ---------- 164 | {1} 165 | (1 row) 166 | 167 | SELECT quantile(x::double precision, ARRAY[1]) FROM generate_series(1,1000) s(x); 168 | quantile 169 | ---------- 170 | {1000} 171 | (1 row) 172 | 173 | SELECT quantile(x::double precision, ARRAY[0, 0.1, 0.5, 0.75, 1]) FROM generate_series(1,1000) s(x); 174 | quantile 175 | ---------------------- 176 | {1,100,500,750,1000} 177 | (1 row) 178 | 179 | -- numeric 180 | SELECT quantile(x::numeric, -0.5) FROM generate_series(1,1000) s(x); 181 | ERROR: invalid percentile value -0.500000 - needs to be in [0,1] 182 | SELECT quantile(x::numeric, 1.5) FROM generate_series(1,1000) s(x); 183 | ERROR: invalid percentile value 1.500000 - needs to be in [0,1] 184 | SELECT quantile(x::numeric, 0.5) FROM generate_series(1,1000) s(x); 185 | quantile 186 | ---------- 187 | 500 188 | (1 row) 189 | 190 | SELECT quantile(x::numeric, 0.1) FROM generate_series(1,1000) s(x); 191 | quantile 192 | ---------- 193 | 100 194 | (1 row) 195 | 196 | SELECT quantile(x::numeric, 0) FROM generate_series(1,1000) s(x); 197 | quantile 198 | ---------- 199 | 1 200 | (1 row) 201 | 202 | SELECT quantile(x::numeric, 1) FROM generate_series(1,1000) s(x); 203 | quantile 204 | ---------- 205 | 1000 206 | (1 row) 207 | 208 | SELECT quantile(x::numeric, ARRAY[0.5]) FROM generate_series(1,1000) s(x); 209 | quantile 210 | ---------- 211 | {500} 212 | (1 row) 213 | 214 | SELECT quantile(x::numeric, ARRAY[0.1]) FROM generate_series(1,1000) s(x); 215 | quantile 216 | ---------- 217 | {100} 218 | (1 row) 219 | 220 | SELECT quantile(x::numeric, ARRAY[0]) FROM generate_series(1,1000) s(x); 221 | quantile 222 | ---------- 223 | {1} 224 | (1 row) 225 | 226 | SELECT quantile(x::numeric, ARRAY[1]) FROM generate_series(1,1000) s(x); 227 | quantile 228 | ---------- 229 | {1000} 230 | (1 row) 231 | 232 | SELECT quantile(x::numeric, ARRAY[0, 0.1, 0.5, 0.75, 1]) FROM generate_series(1,1000) s(x); 233 | quantile 234 | ---------------------- 235 | {1,100,500,750,1000} 236 | (1 row) 237 | 238 | -- test of correct NULL handling (skipping with all NULLS) 239 | CREATE TABLE parent_table (id int); 240 | CREATE TABLE child_table (id int, val int); 241 | INSERT INTO parent_table SELECT i FROM generate_series(1,10) s(i); 242 | INSERT INTO child_table SELECT 2, i FROM generate_series(1,100) s(i); 243 | INSERT INTO child_table SELECT 4, i FROM generate_series(1,100) s(i); 244 | INSERT INTO child_table SELECT 6, i FROM generate_series(1,100) s(i); 245 | INSERT INTO child_table SELECT 8, i FROM generate_series(1,100) s(i); 246 | INSERT INTO child_table SELECT 10, i FROM generate_series(1,100) s(i); 247 | SELECT parent_table.id, quantile(child_table.val, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 248 | id | quantile 249 | ----+------------------------------ 250 | 1 | 251 | 2 | {10,20,30,40,50,60,70,80,90} 252 | 3 | 253 | 4 | {10,20,30,40,50,60,70,80,90} 254 | 5 | 255 | 6 | {10,20,30,40,50,60,70,80,90} 256 | 7 | 257 | 8 | {10,20,30,40,50,60,70,80,90} 258 | 9 | 259 | 10 | {10,20,30,40,50,60,70,80,90} 260 | (10 rows) 261 | 262 | SELECT parent_table.id, quantile(child_table.val, 0.5) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 263 | id | quantile 264 | ----+---------- 265 | 1 | 266 | 2 | 50 267 | 3 | 268 | 4 | 50 269 | 5 | 270 | 6 | 50 271 | 7 | 272 | 8 | 50 273 | 9 | 274 | 10 | 50 275 | (10 rows) 276 | 277 | SELECT parent_table.id, quantile(child_table.val::bigint, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 278 | id | quantile 279 | ----+------------------------------ 280 | 1 | 281 | 2 | {10,20,30,40,50,60,70,80,90} 282 | 3 | 283 | 4 | {10,20,30,40,50,60,70,80,90} 284 | 5 | 285 | 6 | {10,20,30,40,50,60,70,80,90} 286 | 7 | 287 | 8 | {10,20,30,40,50,60,70,80,90} 288 | 9 | 289 | 10 | {10,20,30,40,50,60,70,80,90} 290 | (10 rows) 291 | 292 | SELECT parent_table.id, quantile(child_table.val::bigint, 0.5) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 293 | id | quantile 294 | ----+---------- 295 | 1 | 296 | 2 | 50 297 | 3 | 298 | 4 | 50 299 | 5 | 300 | 6 | 50 301 | 7 | 302 | 8 | 50 303 | 9 | 304 | 10 | 50 305 | (10 rows) 306 | 307 | SELECT parent_table.id, quantile(child_table.val::double precision, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 308 | id | quantile 309 | ----+------------------------------ 310 | 1 | 311 | 2 | {10,20,30,40,50,60,70,80,90} 312 | 3 | 313 | 4 | {10,20,30,40,50,60,70,80,90} 314 | 5 | 315 | 6 | {10,20,30,40,50,60,70,80,90} 316 | 7 | 317 | 8 | {10,20,30,40,50,60,70,80,90} 318 | 9 | 319 | 10 | {10,20,30,40,50,60,70,80,90} 320 | (10 rows) 321 | 322 | SELECT parent_table.id, quantile(child_table.val::double precision, 0.5) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 323 | id | quantile 324 | ----+---------- 325 | 1 | 326 | 2 | 50 327 | 3 | 328 | 4 | 50 329 | 5 | 330 | 6 | 50 331 | 7 | 332 | 8 | 50 333 | 9 | 334 | 10 | 50 335 | (10 rows) 336 | 337 | SELECT parent_table.id, quantile(child_table.val::numeric, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 338 | id | quantile 339 | ----+------------------------------ 340 | 1 | 341 | 2 | {10,20,30,40,50,60,70,80,90} 342 | 3 | 343 | 4 | {10,20,30,40,50,60,70,80,90} 344 | 5 | 345 | 6 | {10,20,30,40,50,60,70,80,90} 346 | 7 | 347 | 8 | {10,20,30,40,50,60,70,80,90} 348 | 9 | 349 | 10 | {10,20,30,40,50,60,70,80,90} 350 | (10 rows) 351 | 352 | SELECT parent_table.id, quantile(child_table.val::numeric, 0.5) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 353 | id | quantile 354 | ----+---------- 355 | 1 | 356 | 2 | 50 357 | 3 | 358 | 4 | 50 359 | 5 | 360 | 6 | 50 361 | 7 | 362 | 8 | 50 363 | 9 | 364 | 10 | 50 365 | (10 rows) 366 | 367 | -- test of correct NULL handling (skipping with mixed NULL and not-NULL values) 368 | TRUNCATE child_table; 369 | INSERT INTO child_table SELECT i, (CASE WHEN MOD(i,2) = 0 THEN i/2 ELSE NULL END) FROM generate_series(1,200) s(i); 370 | SELECT quantile(val, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM (SELECT val FROM child_table ORDER BY id) AS foo; 371 | quantile 372 | ------------------------------ 373 | {10,20,30,40,50,60,70,80,90} 374 | (1 row) 375 | 376 | SELECT quantile(val::bigint, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM (SELECT val FROM child_table ORDER BY id) AS foo; 377 | quantile 378 | ------------------------------ 379 | {10,20,30,40,50,60,70,80,90} 380 | (1 row) 381 | 382 | SELECT quantile(val::double precision, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM (SELECT val FROM child_table ORDER BY id) AS foo; 383 | quantile 384 | ------------------------------ 385 | {10,20,30,40,50,60,70,80,90} 386 | (1 row) 387 | 388 | SELECT quantile(val::numeric, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM (SELECT val FROM child_table ORDER BY id) AS foo; 389 | quantile 390 | ------------------------------ 391 | {10,20,30,40,50,60,70,80,90} 392 | (1 row) 393 | 394 | -------------------------------------------------------------------------------- /test/sql/base.sql: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | 3 | -- disable the notices for the create script (shell types etc.) 4 | SET client_min_messages = 'WARNING'; 5 | \i sql/quantile--1.1.8.sql 6 | SET client_min_messages = 'NOTICE'; 7 | 8 | \set ECHO all 9 | 10 | -- int 11 | SELECT quantile(x, -0.5) FROM generate_series(1,1000) s(x); 12 | SELECT quantile(x, 1.5) FROM generate_series(1,1000) s(x); 13 | SELECT quantile(x, 0.5) FROM generate_series(1,1000) s(x); 14 | SELECT quantile(x, 0.1) FROM generate_series(1,1000) s(x); 15 | SELECT quantile(x, 0) FROM generate_series(1,1000) s(x); 16 | SELECT quantile(x, 1) FROM generate_series(1,1000) s(x); 17 | 18 | SELECT quantile(x, ARRAY[0.5]) FROM generate_series(1,1000) s(x); 19 | SELECT quantile(x, ARRAY[0.1]) FROM generate_series(1,1000) s(x); 20 | SELECT quantile(x, ARRAY[0]) FROM generate_series(1,1000) s(x); 21 | SELECT quantile(x, ARRAY[1]) FROM generate_series(1,1000) s(x); 22 | 23 | SELECT quantile(x, ARRAY[0, 0.1, 0.5, 0.75, 1]) FROM generate_series(1,1000) s(x); 24 | 25 | -- bigint 26 | SELECT quantile(x::bigint, -0.5) FROM generate_series(1,1000) s(x); 27 | SELECT quantile(x::bigint, 1.5) FROM generate_series(1,1000) s(x); 28 | SELECT quantile(x::bigint, 0.5) FROM generate_series(1,1000) s(x); 29 | SELECT quantile(x::bigint, 0.1) FROM generate_series(1,1000) s(x); 30 | SELECT quantile(x::bigint, 0) FROM generate_series(1,1000) s(x); 31 | SELECT quantile(x::bigint, 1) FROM generate_series(1,1000) s(x); 32 | 33 | SELECT quantile(x::bigint, ARRAY[0.5]) FROM generate_series(1,1000) s(x); 34 | SELECT quantile(x::bigint, ARRAY[0.1]) FROM generate_series(1,1000) s(x); 35 | SELECT quantile(x::bigint, ARRAY[0]) FROM generate_series(1,1000) s(x); 36 | SELECT quantile(x::bigint, ARRAY[1]) FROM generate_series(1,1000) s(x); 37 | 38 | SELECT quantile(x::bigint, ARRAY[0, 0.1, 0.5, 0.75, 1]) FROM generate_series(1,1000) s(x); 39 | 40 | -- double precision 41 | SELECT quantile(x::double precision, -0.5) FROM generate_series(1,1000) s(x); 42 | SELECT quantile(x::double precision, 1.5) FROM generate_series(1,1000) s(x); 43 | SELECT quantile(x::double precision, 0.5) FROM generate_series(1,1000) s(x); 44 | SELECT quantile(x::double precision, 0.1) FROM generate_series(1,1000) s(x); 45 | SELECT quantile(x::double precision, 0) FROM generate_series(1,1000) s(x); 46 | SELECT quantile(x::double precision, 1) FROM generate_series(1,1000) s(x); 47 | 48 | SELECT quantile(x::double precision, ARRAY[0.5]) FROM generate_series(1,1000) s(x); 49 | SELECT quantile(x::double precision, ARRAY[0.1]) FROM generate_series(1,1000) s(x); 50 | SELECT quantile(x::double precision, ARRAY[0]) FROM generate_series(1,1000) s(x); 51 | SELECT quantile(x::double precision, ARRAY[1]) FROM generate_series(1,1000) s(x); 52 | 53 | SELECT quantile(x::double precision, ARRAY[0, 0.1, 0.5, 0.75, 1]) FROM generate_series(1,1000) s(x); 54 | 55 | -- numeric 56 | SELECT quantile(x::numeric, -0.5) FROM generate_series(1,1000) s(x); 57 | SELECT quantile(x::numeric, 1.5) FROM generate_series(1,1000) s(x); 58 | SELECT quantile(x::numeric, 0.5) FROM generate_series(1,1000) s(x); 59 | SELECT quantile(x::numeric, 0.1) FROM generate_series(1,1000) s(x); 60 | SELECT quantile(x::numeric, 0) FROM generate_series(1,1000) s(x); 61 | SELECT quantile(x::numeric, 1) FROM generate_series(1,1000) s(x); 62 | 63 | SELECT quantile(x::numeric, ARRAY[0.5]) FROM generate_series(1,1000) s(x); 64 | SELECT quantile(x::numeric, ARRAY[0.1]) FROM generate_series(1,1000) s(x); 65 | SELECT quantile(x::numeric, ARRAY[0]) FROM generate_series(1,1000) s(x); 66 | SELECT quantile(x::numeric, ARRAY[1]) FROM generate_series(1,1000) s(x); 67 | 68 | SELECT quantile(x::numeric, ARRAY[0, 0.1, 0.5, 0.75, 1]) FROM generate_series(1,1000) s(x); 69 | 70 | -- test of correct NULL handling (skipping with all NULLS) 71 | CREATE TABLE parent_table (id int); 72 | CREATE TABLE child_table (id int, val int); 73 | 74 | INSERT INTO parent_table SELECT i FROM generate_series(1,10) s(i); 75 | INSERT INTO child_table SELECT 2, i FROM generate_series(1,100) s(i); 76 | INSERT INTO child_table SELECT 4, i FROM generate_series(1,100) s(i); 77 | INSERT INTO child_table SELECT 6, i FROM generate_series(1,100) s(i); 78 | INSERT INTO child_table SELECT 8, i FROM generate_series(1,100) s(i); 79 | INSERT INTO child_table SELECT 10, i FROM generate_series(1,100) s(i); 80 | 81 | SELECT parent_table.id, quantile(child_table.val, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 82 | SELECT parent_table.id, quantile(child_table.val, 0.5) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 83 | 84 | SELECT parent_table.id, quantile(child_table.val::bigint, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 85 | SELECT parent_table.id, quantile(child_table.val::bigint, 0.5) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 86 | 87 | SELECT parent_table.id, quantile(child_table.val::double precision, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 88 | SELECT parent_table.id, quantile(child_table.val::double precision, 0.5) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 89 | 90 | SELECT parent_table.id, quantile(child_table.val::numeric, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 91 | SELECT parent_table.id, quantile(child_table.val::numeric, 0.5) FROM parent_table LEFT JOIN child_table USING (id) GROUP BY id ORDER BY id; 92 | 93 | -- test of correct NULL handling (skipping with mixed NULL and not-NULL values) 94 | TRUNCATE child_table; 95 | INSERT INTO child_table SELECT i, (CASE WHEN MOD(i,2) = 0 THEN i/2 ELSE NULL END) FROM generate_series(1,200) s(i); 96 | 97 | SELECT quantile(val, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM (SELECT val FROM child_table ORDER BY id) AS foo; 98 | SELECT quantile(val::bigint, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM (SELECT val FROM child_table ORDER BY id) AS foo; 99 | SELECT quantile(val::double precision, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM (SELECT val FROM child_table ORDER BY id) AS foo; 100 | SELECT quantile(val::numeric, array[0.1, 0.2, 0.3, 0.4, 0.5, 0.6, 0.7, 0.8, 0.9]) FROM (SELECT val FROM child_table ORDER BY id) AS foo; 101 | --------------------------------------------------------------------------------