├── .gitattributes ├── .gitignore ├── LICENSE ├── META.json ├── Makefile ├── README.md ├── expected ├── inetrange_test.out ├── init.out ├── range_agg_1_test.out ├── range_agg_2_test.out ├── range_agg_3_test.out └── with_unnest.out ├── range_agg--1.0.0.sql ├── range_agg--1.1.0.sql ├── range_agg--1.2.0.sql ├── range_agg--1.2.1.sql ├── range_agg.c ├── range_agg.control ├── sql ├── inetrange_test.sql ├── init.sql ├── range_agg_1_test.sql ├── range_agg_2_test.sql ├── range_agg_3_test.sql └── with_unnest.sql └── util.c /.gitattributes: -------------------------------------------------------------------------------- 1 | sql/* linguist-vendored 2 | expected/* linguist-vendored 3 | *.sql linguist-vendored linguist-language=SQL 4 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | *.swp 2 | *.swo 3 | 4 | *.s 5 | *.o 6 | *.so 7 | 8 | /regression.diffs 9 | /regression.out 10 | /results 11 | /README.html 12 | 13 | /*.zip 14 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2014 Paul A. Jungwirth 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": "range_agg", 3 | "abstract": "Merge adjacent/overlapping ranges", 4 | "version": "1.2.1", 5 | "maintainer": "Paul A. Jungwirth ", 6 | "license": "mit", 7 | "provides": { 8 | "range_agg": { 9 | "abstract": "Merge adjacent/overlapping ranges", 10 | "file": "range_agg--1.2.1.sql", 11 | "docfile": "README.md", 12 | "version": "1.2.1" 13 | } 14 | }, 15 | "resources": { 16 | "repository": { 17 | "url": "git://github.com/pjungwir/range_agg.git", 18 | "web": "https://github.com/pjungwir/range_agg", 19 | "type": "git" 20 | } 21 | }, 22 | "generated_by": "Paul A. Jungwirth", 23 | "meta-spec": { 24 | "version": "1.0.0", 25 | "url": "http://pgxn.org/meta/spec.txt" 26 | }, 27 | "tags": [ 28 | "arrays", 29 | "ranges", 30 | "aggregates", 31 | "temporal" 32 | ] 33 | } 34 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | MODULES = range_agg 2 | EXTENSION = range_agg 3 | EXTENSION_VERSION = 1.2.1 4 | 5 | DATA = $(EXTENSION)--$(EXTENSION_VERSION).sql 6 | 7 | REGRESS = init \ 8 | range_agg_1_test \ 9 | range_agg_2_test \ 10 | range_agg_3_test \ 11 | inetrange_test \ 12 | with_unnest 13 | 14 | PG_CONFIG = pg_config 15 | PGXS := $(shell $(PG_CONFIG) --pgxs) 16 | include $(PGXS) 17 | 18 | README.html: README.md 19 | jq --slurp --raw-input '{"text": "\(.)", "mode": "markdown"}' < README.md | curl --data @- https://api.github.com/markdown > README.html 20 | 21 | release: 22 | git archive --format zip --prefix=$(EXTENSION)-$(EXTENSION_VERSION)/ --output $(EXTENSION)-$(EXTENSION_VERSION).zip master 23 | 24 | .PHONY: release 25 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | `range_agg` 2 | =========== 3 | 4 | This is a Postgres extension that provides a `range_agg` aggregate function. 5 | It takes any [Postgres range type](https://www.postgresql.org/docs/current/static/rangetypes.html) 6 | and combines them, sort of like 7 | [`string_agg`, `array_agg`, `json_agg`, etc](https://www.postgresql.org/docs/current/static/functions-aggregate.html). 8 | 9 | There are three forms, depending on whether or not you want to permit gaps & overlaps. 10 | If you call `range_agg(anyrange)` (with just a single range parameter), 11 | then it will raise an error if a gap or overlap is detected, 12 | and on success it will return a single range. 13 | 14 | You call also call `range_agg(r anyrange, permit_gaps boolean, permit_overlaps boolean)`, 15 | and it will return an *array* of ranges. 16 | It will still merge adjacent/overlapping ranges as much as possible, 17 | but it will add a new array element whenever there is a gap. 18 | So if your group had these ranges: 19 | 20 | [2018-07-01,2018-07-15) 21 | [2018-07-15,2018-07-31) 22 | [2018-09-01,2018-09-15) 23 | 24 | Then you would get back: 25 | 26 | {"[2018-07-01,2018-07-31)", "[2018-09-01,2018-09-15)"} 27 | 28 | You can also choose to raise an exception 29 | on either an overlap or a gap, 30 | by setting the respective parameter to `false`. 31 | 32 | Finally there is a two-param version, 33 | `range_agg(r anyrange, permit_gaps boolean)`, 34 | which will raise on overlaps but permits gaps (if passed `true`). 35 | This is likely most useful for coalescing rows in a temporal table (see below). 36 | 37 | With temporal databases 38 | ----------------------- 39 | 40 | The primary motivation of this extension is to let you "coalesce" rows in a temporal database, 41 | as described in section 6.5.2 of Snodgrass's book 42 | [Developing Time-Oriented Database Applications in SQL](https://www2.cs.arizona.edu/~rts/publications.html). 43 | You can use the three-param version of the function to permit gaps 44 | (still forbidding overlaps if you like), 45 | and then `UNNEST` on the resulting range array, like so: 46 | 47 | SELECT room_id, t2.booked_during 48 | FROM ( 49 | SELECT room_id, range_agg(booked_during, true) AS booked_during 50 | FROM reservations 51 | GROUP BY room_id 52 | ) AS t1, 53 | UNNEST(t1.booked_during) AS t2(booked_during) 54 | ORDER BY room_id, booked_during 55 | ; 56 | room_id | booked_during 57 | ---------+------------------------- 58 | 1 | [07-01-2018,07-14-2018) 59 | 1 | [07-20-2018,07-22-2018) 60 | 2 | [07-01-2018,07-03-2018) 61 | 5 | [07-01-2018,07-03-2018) 62 | 6 | [07-01-2018,07-10-2018) 63 | 7 | [07-01-2018,07-14-2018) 64 | (6 rows) 65 | 66 | 67 | Custom Ranges 68 | ------------- 69 | 70 | There is a small caveat about using custom range types. 71 | The one-parameter version of `range_agg` will support them automatically, 72 | but the two- and three-parameter versions take a little more work. 73 | [Postgres has no way to declare a function that takes `anyrange` and returns `anyrange[]`](https://www.postgresql.org/message-id/CA%2BrenyVOjb4xQZGjdCnA54-1nzVSY%2B47-h4nkM-EP5J%3D1z%3Db9w%40mail.gmail.com), 74 | so we have separate declarations for `int4range`, `int8range`, etc. 75 | Out of the box we support all built-in range types. 76 | If you want to support a new one, e.g. `inetrange`, just run these commands 77 | (after creating the extension): 78 | 79 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, inetrange, boolean) 80 | RETURNS internal 81 | AS 'range_agg', 'range_agg_transfn' 82 | LANGUAGE c IMMUTABLE; 83 | 84 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, inetrange, boolean) 85 | RETURNS inetrange[] 86 | AS 'range_agg', 'range_agg_finalfn' 87 | LANGUAGE c IMMUTABLE; 88 | 89 | CREATE AGGREGATE range_agg(inetrange, boolean) ( 90 | stype = internal, 91 | sfunc = range_agg_transfn, 92 | finalfunc = range_agg_finalfn, 93 | finalfunc_extra 94 | ); 95 | 96 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, inetrange, boolean, boolean) 97 | RETURNS internal 98 | AS 'range_agg', 'range_agg_transfn' 99 | LANGUAGE c IMMUTABLE; 100 | 101 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, inetrange, boolean, boolean) 102 | RETURNS inetrange[] 103 | AS 'range_agg', 'range_agg_finalfn' 104 | LANGUAGE c IMMUTABLE; 105 | 106 | CREATE AGGREGATE range_agg(inetrange, boolean, boolean) ( 107 | stype = internal, 108 | sfunc = range_agg_transfn, 109 | finalfunc = range_agg_finalfn, 110 | finalfunc_extra 111 | ); 112 | 113 | 114 | (Replace `inetrange` with your own range type, of course.) 115 | 116 | 117 | Installing 118 | ---------- 119 | 120 | This package installs like any Postgres extension. First say: 121 | 122 | make && sudo make install 123 | 124 | You will need to have `pg_config` in your path, 125 | but normally that is already the case. 126 | You can check with `which pg_config`. 127 | 128 | Then in the database of your choice say: 129 | 130 | CREATE EXTENSION range_agg; 131 | 132 | 133 | TODO 134 | ---- 135 | 136 | - Add a function to find gaps (see below). 137 | 138 | 139 | Author 140 | ------ 141 | 142 | Paul A. Jungwirth 143 | 144 | This extension was inspired by a blog post about aggregating ranges by [Matt Schinckel](http://schinckel.net/2014/11/18/aggregating-ranges-in-postgres/). 145 | He talks about merging ranges (like we do here) 146 | and a related problem---finding the gaps between them---which I think would be nice to support here too. (Watch this space for updates. :-) 147 | I was impressed by his solution, 148 | which is original as far as I know, 149 | of using [the `lead` window function](https://www.postgresql.org/docs/current/static/functions-window.html). 150 | 151 | 152 | License 153 | ------- 154 | 155 | Copyright (c) 2018 Paul A. Jungwirth 156 | 157 | 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: 158 | 159 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. 160 | 161 | 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. 162 | -------------------------------------------------------------------------------- /expected/inetrange_test.out: -------------------------------------------------------------------------------- 1 | -- Verify that it works on custom range types: 2 | CREATE OR REPLACE FUNCTION inet_diff(x inet, y inet) 3 | RETURNS DOUBLE PRECISION AS 4 | $$ 5 | DECLARE 6 | BEGIN 7 | RETURN x - y; 8 | END; 9 | $$ 10 | LANGUAGE 'plpgsql' STRICT IMMUTABLE; 11 | CREATE TYPE inetrange AS RANGE ( 12 | subtype = inet, 13 | subtype_diff = inet_diff 14 | ); 15 | SELECT range_agg(r) 16 | FROM (VALUES 17 | (inetrange('1.2.3.0', '1.2.4.0', '[)')), 18 | (inetrange('1.2.4.0', '1.2.5.0', '[)')) 19 | ) t(r); 20 | range_agg 21 | ------------------- 22 | [1.2.3.0,1.2.5.0) 23 | (1 row) 24 | 25 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, inetrange, boolean) 26 | RETURNS internal 27 | AS 'range_agg', 'range_agg_transfn' 28 | LANGUAGE c IMMUTABLE; 29 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, inetrange, boolean) 30 | RETURNS inetrange[] 31 | AS 'range_agg', 'range_agg_finalfn' 32 | LANGUAGE c IMMUTABLE; 33 | CREATE AGGREGATE range_agg(inetrange, boolean) ( 34 | stype = internal, 35 | sfunc = range_agg_transfn, 36 | finalfunc = range_agg_finalfn, 37 | finalfunc_extra 38 | ); 39 | SELECT range_agg(r, true) 40 | FROM (VALUES 41 | (inetrange('1.2.3.0', '1.2.3.128', '[)')), 42 | (inetrange('1.2.4.0', '1.2.5.0', '[)')) 43 | ) t(r); 44 | range_agg 45 | --------------------------------------------- 46 | {"[1.2.3.0,1.2.3.128)","[1.2.4.0,1.2.5.0)"} 47 | (1 row) 48 | 49 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, inetrange, boolean, boolean) 50 | RETURNS internal 51 | AS 'range_agg', 'range_agg_transfn' 52 | LANGUAGE c IMMUTABLE; 53 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, inetrange, boolean, boolean) 54 | RETURNS inetrange[] 55 | AS 'range_agg', 'range_agg_finalfn' 56 | LANGUAGE c IMMUTABLE; 57 | CREATE AGGREGATE range_agg(inetrange, boolean, boolean) ( 58 | stype = internal, 59 | sfunc = range_agg_transfn, 60 | finalfunc = range_agg_finalfn, 61 | finalfunc_extra 62 | ); 63 | SELECT range_agg(r, true, true) 64 | FROM (VALUES 65 | (inetrange('1.2.3.0', '1.2.3.128', '[)')), 66 | (inetrange('1.2.4.0', '1.2.5.0', '[)')) 67 | ) t(r); 68 | range_agg 69 | --------------------------------------------- 70 | {"[1.2.3.0,1.2.3.128)","[1.2.4.0,1.2.5.0)"} 71 | (1 row) 72 | 73 | -------------------------------------------------------------------------------- /expected/init.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION range_agg; 2 | CREATE TABLE reservations ( 3 | room_id INTEGER NOT NULL, 4 | booked_during daterange 5 | ); 6 | INSERT INTO reservations 7 | (room_id, booked_during) 8 | VALUES 9 | -- 1: has a meets and a gap 10 | (1, daterange('2018-07-01', '2018-07-07')), 11 | (1, daterange('2018-07-07', '2018-07-14')), 12 | (1, daterange('2018-07-20', '2018-07-22')), 13 | -- 2: just a single row 14 | (2, daterange('2018-07-01', '2018-07-03')), 15 | -- 3: one null range 16 | (3, NULL), 17 | -- 4: two null ranges 18 | (4, NULL), 19 | (4, NULL), 20 | -- 5: a null range and a non-null range 21 | (5, NULL), 22 | (5, daterange('2018-07-01', '2018-07-03')), 23 | -- 6: has overlap 24 | (6, daterange('2018-07-01', '2018-07-07')), 25 | (6, daterange('2018-07-05', '2018-07-10')), 26 | -- 7: two ranges that meet: no gap or overlap 27 | (7, daterange('2018-07-01', '2018-07-07')), 28 | (7, daterange('2018-07-07', '2018-07-14')) 29 | ; 30 | -------------------------------------------------------------------------------- /expected/range_agg_1_test.out: -------------------------------------------------------------------------------- 1 | -- 2 | -- 3 | -- Forbidding gaps and overlaps: 4 | -- 5 | -- 6 | SELECT room_id, range_agg(booked_during) 7 | FROM reservations 8 | WHERE room_id = 1 9 | GROUP BY room_id 10 | ORDER BY room_id; 11 | ERROR: range_agg: gap detected between lastRange and currentRange 12 | SELECT room_id, range_agg(booked_during) 13 | FROM reservations 14 | WHERE room_id = 6 15 | GROUP BY room_id 16 | ORDER BY room_id; 17 | ERROR: range_agg: overlap detected between lastRange and currentRange 18 | SELECT room_id, range_agg(booked_during) 19 | FROM reservations 20 | WHERE room_id NOT IN (1, 6) 21 | GROUP BY room_id 22 | ORDER BY room_id; 23 | room_id | range_agg 24 | ---------+------------------------- 25 | 2 | [07-01-2018,07-03-2018) 26 | 3 | 27 | 4 | 28 | 5 | [07-01-2018,07-03-2018) 29 | 7 | [07-01-2018,07-14-2018) 30 | (5 rows) 31 | 32 | -- 33 | -- 34 | -- Obeying discrete base types: 35 | -- 36 | -- 37 | SELECT range_agg(r) 38 | FROM (VALUES 39 | (int4range( 0, 9, '[]')), 40 | (int4range(10, 19, '[]')) 41 | ) t(r); 42 | range_agg 43 | ----------- 44 | [0,20) 45 | (1 row) 46 | 47 | -------------------------------------------------------------------------------- /expected/range_agg_2_test.out: -------------------------------------------------------------------------------- 1 | -- 2 | -- 3 | -- Forbidding gaps (and overlaps): 4 | -- 5 | -- 6 | SELECT room_id, range_agg(booked_during, false) 7 | FROM reservations 8 | WHERE room_id = 1 9 | GROUP BY room_id; 10 | ERROR: range_agg: gap detected between lastRange and currentRange 11 | SELECT room_id, range_agg(booked_during, false) 12 | FROM reservations 13 | WHERE room_id = 6 14 | GROUP BY room_id; 15 | ERROR: range_agg: overlap detected between lastRange and currentRange 16 | SELECT room_id, range_agg(booked_during, false) 17 | FROM reservations 18 | WHERE room_id NOT IN (1, 6) 19 | GROUP BY room_id; 20 | room_id | range_agg 21 | ---------+----------------------------- 22 | 4 | 23 | 5 | {"[07-01-2018,07-03-2018)"} 24 | 3 | 25 | 2 | {"[07-01-2018,07-03-2018)"} 26 | 7 | {"[07-01-2018,07-14-2018)"} 27 | (5 rows) 28 | 29 | -- 30 | -- 31 | -- Permitting gaps (but forbidding overlaps): 32 | -- 33 | -- 34 | SELECT room_id, range_agg(booked_during, true) 35 | FROM reservations 36 | WHERE room_id = 1 37 | GROUP BY room_id; 38 | room_id | range_agg 39 | ---------+------------------------------------------------------- 40 | 1 | {"[07-01-2018,07-14-2018)","[07-20-2018,07-22-2018)"} 41 | (1 row) 42 | 43 | SELECT room_id, range_agg(booked_during, true) 44 | FROM reservations 45 | WHERE room_id = 6 46 | GROUP BY room_id; 47 | ERROR: range_agg: overlap detected between lastRange and currentRange 48 | SELECT room_id, range_agg(booked_during, true) 49 | FROM reservations 50 | WHERE room_id NOT IN (1, 6) 51 | GROUP BY room_id; 52 | room_id | range_agg 53 | ---------+----------------------------- 54 | 4 | 55 | 5 | {"[07-01-2018,07-03-2018)"} 56 | 3 | 57 | 2 | {"[07-01-2018,07-03-2018)"} 58 | 7 | {"[07-01-2018,07-14-2018)"} 59 | (5 rows) 60 | 61 | -------------------------------------------------------------------------------- /expected/range_agg_3_test.out: -------------------------------------------------------------------------------- 1 | -- 2 | -- 3 | -- Forbidding gaps and overlaps: 4 | -- 5 | -- 6 | SELECT room_id, range_agg(booked_during, false, false) 7 | FROM reservations 8 | WHERE room_id = 1 9 | GROUP BY room_id; 10 | ERROR: range_agg: gap detected between lastRange and currentRange 11 | SELECT room_id, range_agg(booked_during, false, false) 12 | FROM reservations 13 | WHERE room_id = 6 14 | GROUP BY room_id; 15 | ERROR: range_agg: overlap detected between lastRange and currentRange 16 | SELECT room_id, range_agg(booked_during, false, false) 17 | FROM reservations 18 | WHERE room_id NOT IN (1, 6) 19 | GROUP BY room_id; 20 | room_id | range_agg 21 | ---------+----------------------------- 22 | 4 | 23 | 5 | {"[07-01-2018,07-03-2018)"} 24 | 3 | 25 | 2 | {"[07-01-2018,07-03-2018)"} 26 | 7 | {"[07-01-2018,07-14-2018)"} 27 | (5 rows) 28 | 29 | -- 30 | -- 31 | -- Forbidding gaps but permitting overlaps 32 | -- 33 | -- 34 | SELECT room_id, range_agg(booked_during, false, true) 35 | FROM reservations 36 | WHERE room_id = 1 37 | GROUP BY room_id; 38 | ERROR: range_agg: gap detected between lastRange and currentRange 39 | SELECT room_id, range_agg(booked_during, false, true) 40 | FROM reservations 41 | WHERE room_id = 6 42 | GROUP BY room_id; 43 | room_id | range_agg 44 | ---------+----------------------------- 45 | 6 | {"[07-01-2018,07-10-2018)"} 46 | (1 row) 47 | 48 | SELECT room_id, range_agg(booked_during, false, true) 49 | FROM reservations 50 | WHERE room_id NOT IN (1, 6) 51 | GROUP BY room_id; 52 | room_id | range_agg 53 | ---------+----------------------------- 54 | 4 | 55 | 5 | {"[07-01-2018,07-03-2018)"} 56 | 3 | 57 | 2 | {"[07-01-2018,07-03-2018)"} 58 | 7 | {"[07-01-2018,07-14-2018)"} 59 | (5 rows) 60 | 61 | -- 62 | -- 63 | -- Permitting gaps but forbidding overlaps 64 | -- 65 | -- 66 | SELECT room_id, range_agg(booked_during, true, false) 67 | FROM reservations 68 | WHERE room_id = 1 69 | GROUP BY room_id; 70 | room_id | range_agg 71 | ---------+------------------------------------------------------- 72 | 1 | {"[07-01-2018,07-14-2018)","[07-20-2018,07-22-2018)"} 73 | (1 row) 74 | 75 | SELECT room_id, range_agg(booked_during, true, false) 76 | FROM reservations 77 | WHERE room_id = 6 78 | GROUP BY room_id; 79 | ERROR: range_agg: overlap detected between lastRange and currentRange 80 | SELECT room_id, range_agg(booked_during, true, false) 81 | FROM reservations 82 | WHERE room_id NOT IN (1, 6) 83 | GROUP BY room_id; 84 | room_id | range_agg 85 | ---------+----------------------------- 86 | 4 | 87 | 5 | {"[07-01-2018,07-03-2018)"} 88 | 3 | 89 | 2 | {"[07-01-2018,07-03-2018)"} 90 | 7 | {"[07-01-2018,07-14-2018)"} 91 | (5 rows) 92 | 93 | -- 94 | -- 95 | -- Permitting gaps and overlaps: 96 | -- 97 | -- 98 | SELECT room_id, range_agg(booked_during, true, true) 99 | FROM reservations 100 | WHERE room_id = 1 101 | GROUP BY room_id; 102 | room_id | range_agg 103 | ---------+------------------------------------------------------- 104 | 1 | {"[07-01-2018,07-14-2018)","[07-20-2018,07-22-2018)"} 105 | (1 row) 106 | 107 | SELECT room_id, range_agg(booked_during, true, true) 108 | FROM reservations 109 | WHERE room_id = 6 110 | GROUP BY room_id; 111 | room_id | range_agg 112 | ---------+----------------------------- 113 | 6 | {"[07-01-2018,07-10-2018)"} 114 | (1 row) 115 | 116 | SELECT room_id, range_agg(booked_during, true, true) 117 | FROM reservations 118 | WHERE room_id NOT IN (1, 6) 119 | GROUP BY room_id; 120 | room_id | range_agg 121 | ---------+----------------------------- 122 | 4 | 123 | 5 | {"[07-01-2018,07-03-2018)"} 124 | 3 | 125 | 2 | {"[07-01-2018,07-03-2018)"} 126 | 7 | {"[07-01-2018,07-14-2018)"} 127 | (5 rows) 128 | 129 | -- 130 | -- 131 | -- Obeying discrete base types: 132 | -- 133 | -- 134 | SELECT range_agg(r, false, false) 135 | FROM (VALUES 136 | (int4range( 0, 5, '[]')), 137 | (int4range( 7, 9, '[]')) 138 | ) t(r); 139 | ERROR: range_agg: gap detected between lastRange and currentRange 140 | SELECT range_agg(r, false, false) 141 | FROM (VALUES 142 | (int4range( 0, 5, '[]')), 143 | (int4range( 5, 9, '[]')) 144 | ) t(r); 145 | ERROR: range_agg: overlap detected between lastRange and currentRange 146 | SELECT range_agg(r, true, true) 147 | FROM (VALUES 148 | (int4range( 0, 9, '[]')), 149 | (int4range(10, 15, '[]')), 150 | (int4range(20, 26, '[]')), 151 | (int4range(26, 29, '[]')) 152 | ) t(r); 153 | range_agg 154 | ---------------------- 155 | {"[0,16)","[20,30)"} 156 | (1 row) 157 | 158 | -------------------------------------------------------------------------------- /expected/with_unnest.out: -------------------------------------------------------------------------------- 1 | -- It combines with UNNEST 2 | -- to implement the temporal database "coalesce" function 3 | -- (see Snodgrass 6.5.2): 4 | SELECT room_id, t2.booked_during 5 | FROM ( 6 | SELECT room_id, range_agg(booked_during, true, true) AS booked_during 7 | FROM reservations 8 | GROUP BY room_id 9 | ) AS t1, 10 | UNNEST(t1.booked_during) AS t2(booked_during) 11 | ORDER BY room_id, booked_during 12 | ; 13 | room_id | booked_during 14 | ---------+------------------------- 15 | 1 | [07-01-2018,07-14-2018) 16 | 1 | [07-20-2018,07-22-2018) 17 | 2 | [07-01-2018,07-03-2018) 18 | 5 | [07-01-2018,07-03-2018) 19 | 6 | [07-01-2018,07-10-2018) 20 | 7 | [07-01-2018,07-14-2018) 21 | (6 rows) 22 | 23 | -------------------------------------------------------------------------------- /range_agg--1.0.0.sql: -------------------------------------------------------------------------------- 1 | /* range_agg--1.0.0.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "CREATE EXTENSION range_agg" to load this file. \quit 5 | 6 | 7 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, anyrange) 8 | RETURNS internal 9 | AS 'range_agg', 'range_agg_transfn' 10 | LANGUAGE c IMMUTABLE; 11 | 12 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, anyrange) 13 | RETURNS anyrange 14 | AS 'range_agg', 'range_agg_finalfn' 15 | LANGUAGE c IMMUTABLE; 16 | 17 | CREATE AGGREGATE range_agg(anyrange) ( 18 | stype = internal, 19 | sfunc = range_agg_transfn, 20 | finalfunc = range_agg_finalfn, 21 | finalfunc_extra 22 | ); 23 | 24 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int4range, boolean, boolean) 25 | RETURNS internal 26 | AS 'range_agg', 'range_agg_transfn' 27 | LANGUAGE c IMMUTABLE; 28 | 29 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int4range, boolean, boolean) 30 | RETURNS int4range[] 31 | AS 'range_agg', 'range_agg_finalfn' 32 | LANGUAGE c IMMUTABLE; 33 | 34 | CREATE AGGREGATE range_agg(int4range, boolean, boolean) ( 35 | stype = internal, 36 | sfunc = range_agg_transfn, 37 | finalfunc = range_agg_finalfn, 38 | finalfunc_extra 39 | ); 40 | 41 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int8range, boolean, boolean) 42 | RETURNS internal 43 | AS 'range_agg', 'range_agg_transfn' 44 | LANGUAGE c IMMUTABLE; 45 | 46 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int8range, boolean, boolean) 47 | RETURNS int8range[] 48 | AS 'range_agg', 'range_agg_finalfn' 49 | LANGUAGE c IMMUTABLE; 50 | 51 | CREATE AGGREGATE range_agg(int8range, boolean, boolean) ( 52 | stype = internal, 53 | sfunc = range_agg_transfn, 54 | finalfunc = range_agg_finalfn, 55 | finalfunc_extra 56 | ); 57 | 58 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, numrange, boolean, boolean) 59 | RETURNS internal 60 | AS 'range_agg', 'range_agg_transfn' 61 | LANGUAGE c IMMUTABLE; 62 | 63 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, numrange, boolean, boolean) 64 | RETURNS numrange[] 65 | AS 'range_agg', 'range_agg_finalfn' 66 | LANGUAGE c IMMUTABLE; 67 | 68 | CREATE AGGREGATE range_agg(numrange, boolean, boolean) ( 69 | stype = internal, 70 | sfunc = range_agg_transfn, 71 | finalfunc = range_agg_finalfn, 72 | finalfunc_extra 73 | ); 74 | 75 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tsrange, boolean, boolean) 76 | RETURNS internal 77 | AS 'range_agg', 'range_agg_transfn' 78 | LANGUAGE c IMMUTABLE; 79 | 80 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tsrange, boolean, boolean) 81 | RETURNS tsrange[] 82 | AS 'range_agg', 'range_agg_finalfn' 83 | LANGUAGE c IMMUTABLE; 84 | 85 | CREATE AGGREGATE range_agg(tsrange, boolean, boolean) ( 86 | stype = internal, 87 | sfunc = range_agg_transfn, 88 | finalfunc = range_agg_finalfn, 89 | finalfunc_extra 90 | ); 91 | 92 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tstzrange, boolean, boolean) 93 | RETURNS internal 94 | AS 'range_agg', 'range_agg_transfn' 95 | LANGUAGE c IMMUTABLE; 96 | 97 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tstzrange, boolean, boolean) 98 | RETURNS tstzrange[] 99 | AS 'range_agg', 'range_agg_finalfn' 100 | LANGUAGE c IMMUTABLE; 101 | 102 | CREATE AGGREGATE range_agg(tstzrange, boolean, boolean) ( 103 | stype = internal, 104 | sfunc = range_agg_transfn, 105 | finalfunc = range_agg_finalfn, 106 | finalfunc_extra 107 | ); 108 | 109 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, daterange, boolean, boolean) 110 | RETURNS internal 111 | AS 'range_agg', 'range_agg_transfn' 112 | LANGUAGE c IMMUTABLE; 113 | 114 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, daterange, boolean, boolean) 115 | RETURNS daterange[] 116 | AS 'range_agg', 'range_agg_finalfn' 117 | LANGUAGE c IMMUTABLE; 118 | 119 | CREATE AGGREGATE range_agg(daterange, boolean, boolean) ( 120 | stype = internal, 121 | sfunc = range_agg_transfn, 122 | finalfunc = range_agg_finalfn, 123 | finalfunc_extra 124 | ); 125 | -------------------------------------------------------------------------------- /range_agg--1.1.0.sql: -------------------------------------------------------------------------------- 1 | /* range_agg--1.1.0.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "CREATE EXTENSION range_agg" to load this file. \quit 5 | 6 | 7 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, anyrange) 8 | RETURNS internal 9 | AS 'range_agg', 'range_agg_transfn' 10 | LANGUAGE c IMMUTABLE; 11 | 12 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, anyrange) 13 | RETURNS anyrange 14 | AS 'range_agg', 'range_agg_finalfn' 15 | LANGUAGE c IMMUTABLE; 16 | 17 | CREATE AGGREGATE range_agg(anyrange) ( 18 | stype = internal, 19 | sfunc = range_agg_transfn, 20 | finalfunc = range_agg_finalfn, 21 | finalfunc_extra 22 | ); 23 | 24 | -- 2- and 3-parameter versions must be defined for each range type: 25 | 26 | -- int4range 27 | 28 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int4range, boolean) 29 | RETURNS internal 30 | AS 'range_agg', 'range_agg_transfn' 31 | LANGUAGE c IMMUTABLE; 32 | 33 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int4range, boolean) 34 | RETURNS int4range[] 35 | AS 'range_agg', 'range_agg_finalfn' 36 | LANGUAGE c IMMUTABLE; 37 | 38 | CREATE AGGREGATE range_agg(int4range, boolean) ( 39 | stype = internal, 40 | sfunc = range_agg_transfn, 41 | finalfunc = range_agg_finalfn, 42 | finalfunc_extra 43 | ); 44 | 45 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int4range, boolean, boolean) 46 | RETURNS internal 47 | AS 'range_agg', 'range_agg_transfn' 48 | LANGUAGE c IMMUTABLE; 49 | 50 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int4range, boolean, boolean) 51 | RETURNS int4range[] 52 | AS 'range_agg', 'range_agg_finalfn' 53 | LANGUAGE c IMMUTABLE; 54 | 55 | CREATE AGGREGATE range_agg(int4range, boolean, boolean) ( 56 | stype = internal, 57 | sfunc = range_agg_transfn, 58 | finalfunc = range_agg_finalfn, 59 | finalfunc_extra 60 | ); 61 | 62 | -- int8range 63 | 64 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int8range, boolean) 65 | RETURNS internal 66 | AS 'range_agg', 'range_agg_transfn' 67 | LANGUAGE c IMMUTABLE; 68 | 69 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int8range, boolean) 70 | RETURNS int8range[] 71 | AS 'range_agg', 'range_agg_finalfn' 72 | LANGUAGE c IMMUTABLE; 73 | 74 | CREATE AGGREGATE range_agg(int8range, boolean) ( 75 | stype = internal, 76 | sfunc = range_agg_transfn, 77 | finalfunc = range_agg_finalfn, 78 | finalfunc_extra 79 | ); 80 | 81 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int8range, boolean, boolean) 82 | RETURNS internal 83 | AS 'range_agg', 'range_agg_transfn' 84 | LANGUAGE c IMMUTABLE; 85 | 86 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int8range, boolean, boolean) 87 | RETURNS int8range[] 88 | AS 'range_agg', 'range_agg_finalfn' 89 | LANGUAGE c IMMUTABLE; 90 | 91 | CREATE AGGREGATE range_agg(int8range, boolean, boolean) ( 92 | stype = internal, 93 | sfunc = range_agg_transfn, 94 | finalfunc = range_agg_finalfn, 95 | finalfunc_extra 96 | ); 97 | 98 | -- numrange 99 | 100 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, numrange, boolean) 101 | RETURNS internal 102 | AS 'range_agg', 'range_agg_transfn' 103 | LANGUAGE c IMMUTABLE; 104 | 105 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, numrange, boolean) 106 | RETURNS numrange[] 107 | AS 'range_agg', 'range_agg_finalfn' 108 | LANGUAGE c IMMUTABLE; 109 | 110 | CREATE AGGREGATE range_agg(numrange, boolean) ( 111 | stype = internal, 112 | sfunc = range_agg_transfn, 113 | finalfunc = range_agg_finalfn, 114 | finalfunc_extra 115 | ); 116 | 117 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, numrange, boolean, boolean) 118 | RETURNS internal 119 | AS 'range_agg', 'range_agg_transfn' 120 | LANGUAGE c IMMUTABLE; 121 | 122 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, numrange, boolean, boolean) 123 | RETURNS numrange[] 124 | AS 'range_agg', 'range_agg_finalfn' 125 | LANGUAGE c IMMUTABLE; 126 | 127 | CREATE AGGREGATE range_agg(numrange, boolean, boolean) ( 128 | stype = internal, 129 | sfunc = range_agg_transfn, 130 | finalfunc = range_agg_finalfn, 131 | finalfunc_extra 132 | ); 133 | 134 | -- tsrange 135 | 136 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tsrange, boolean) 137 | RETURNS internal 138 | AS 'range_agg', 'range_agg_transfn' 139 | LANGUAGE c IMMUTABLE; 140 | 141 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tsrange, boolean) 142 | RETURNS tsrange[] 143 | AS 'range_agg', 'range_agg_finalfn' 144 | LANGUAGE c IMMUTABLE; 145 | 146 | CREATE AGGREGATE range_agg(tsrange, boolean) ( 147 | stype = internal, 148 | sfunc = range_agg_transfn, 149 | finalfunc = range_agg_finalfn, 150 | finalfunc_extra 151 | ); 152 | 153 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tsrange, boolean, boolean) 154 | RETURNS internal 155 | AS 'range_agg', 'range_agg_transfn' 156 | LANGUAGE c IMMUTABLE; 157 | 158 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tsrange, boolean, boolean) 159 | RETURNS tsrange[] 160 | AS 'range_agg', 'range_agg_finalfn' 161 | LANGUAGE c IMMUTABLE; 162 | 163 | CREATE AGGREGATE range_agg(tsrange, boolean, boolean) ( 164 | stype = internal, 165 | sfunc = range_agg_transfn, 166 | finalfunc = range_agg_finalfn, 167 | finalfunc_extra 168 | ); 169 | 170 | -- tstzrange 171 | 172 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tstzrange, boolean) 173 | RETURNS internal 174 | AS 'range_agg', 'range_agg_transfn' 175 | LANGUAGE c IMMUTABLE; 176 | 177 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tstzrange, boolean) 178 | RETURNS tstzrange[] 179 | AS 'range_agg', 'range_agg_finalfn' 180 | LANGUAGE c IMMUTABLE; 181 | 182 | CREATE AGGREGATE range_agg(tstzrange, boolean) ( 183 | stype = internal, 184 | sfunc = range_agg_transfn, 185 | finalfunc = range_agg_finalfn, 186 | finalfunc_extra 187 | ); 188 | 189 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tstzrange, boolean, boolean) 190 | RETURNS internal 191 | AS 'range_agg', 'range_agg_transfn' 192 | LANGUAGE c IMMUTABLE; 193 | 194 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tstzrange, boolean, boolean) 195 | RETURNS tstzrange[] 196 | AS 'range_agg', 'range_agg_finalfn' 197 | LANGUAGE c IMMUTABLE; 198 | 199 | CREATE AGGREGATE range_agg(tstzrange, boolean, boolean) ( 200 | stype = internal, 201 | sfunc = range_agg_transfn, 202 | finalfunc = range_agg_finalfn, 203 | finalfunc_extra 204 | ); 205 | 206 | -- daterange 207 | 208 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, daterange, boolean) 209 | RETURNS internal 210 | AS 'range_agg', 'range_agg_transfn' 211 | LANGUAGE c IMMUTABLE; 212 | 213 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, daterange, boolean) 214 | RETURNS daterange[] 215 | AS 'range_agg', 'range_agg_finalfn' 216 | LANGUAGE c IMMUTABLE; 217 | 218 | CREATE AGGREGATE range_agg(daterange, boolean) ( 219 | stype = internal, 220 | sfunc = range_agg_transfn, 221 | finalfunc = range_agg_finalfn, 222 | finalfunc_extra 223 | ); 224 | 225 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, daterange, boolean, boolean) 226 | RETURNS internal 227 | AS 'range_agg', 'range_agg_transfn' 228 | LANGUAGE c IMMUTABLE; 229 | 230 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, daterange, boolean, boolean) 231 | RETURNS daterange[] 232 | AS 'range_agg', 'range_agg_finalfn' 233 | LANGUAGE c IMMUTABLE; 234 | 235 | CREATE AGGREGATE range_agg(daterange, boolean, boolean) ( 236 | stype = internal, 237 | sfunc = range_agg_transfn, 238 | finalfunc = range_agg_finalfn, 239 | finalfunc_extra 240 | ); 241 | -------------------------------------------------------------------------------- /range_agg--1.2.0.sql: -------------------------------------------------------------------------------- 1 | /* range_agg--1.2.0.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "CREATE EXTENSION range_agg" to load this file. \quit 5 | 6 | 7 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, anyrange) 8 | RETURNS internal 9 | AS 'range_agg', 'range_agg_transfn' 10 | LANGUAGE c IMMUTABLE; 11 | 12 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, anyrange) 13 | RETURNS anyrange 14 | AS 'range_agg', 'range_agg_finalfn' 15 | LANGUAGE c IMMUTABLE; 16 | 17 | CREATE AGGREGATE range_agg(anyrange) ( 18 | stype = internal, 19 | sfunc = range_agg_transfn, 20 | finalfunc = range_agg_finalfn, 21 | finalfunc_extra 22 | ); 23 | 24 | -- 2- and 3-parameter versions must be defined for each range type: 25 | 26 | -- int4range 27 | 28 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int4range, boolean) 29 | RETURNS internal 30 | AS 'range_agg', 'range_agg_transfn' 31 | LANGUAGE c IMMUTABLE; 32 | 33 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int4range, boolean) 34 | RETURNS int4range[] 35 | AS 'range_agg', 'range_agg_finalfn' 36 | LANGUAGE c IMMUTABLE; 37 | 38 | CREATE AGGREGATE range_agg(int4range, boolean) ( 39 | stype = internal, 40 | sfunc = range_agg_transfn, 41 | finalfunc = range_agg_finalfn, 42 | finalfunc_extra 43 | ); 44 | 45 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int4range, boolean, boolean) 46 | RETURNS internal 47 | AS 'range_agg', 'range_agg_transfn' 48 | LANGUAGE c IMMUTABLE; 49 | 50 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int4range, boolean, boolean) 51 | RETURNS int4range[] 52 | AS 'range_agg', 'range_agg_finalfn' 53 | LANGUAGE c IMMUTABLE; 54 | 55 | CREATE AGGREGATE range_agg(int4range, boolean, boolean) ( 56 | stype = internal, 57 | sfunc = range_agg_transfn, 58 | finalfunc = range_agg_finalfn, 59 | finalfunc_extra 60 | ); 61 | 62 | -- int8range 63 | 64 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int8range, boolean) 65 | RETURNS internal 66 | AS 'range_agg', 'range_agg_transfn' 67 | LANGUAGE c IMMUTABLE; 68 | 69 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int8range, boolean) 70 | RETURNS int8range[] 71 | AS 'range_agg', 'range_agg_finalfn' 72 | LANGUAGE c IMMUTABLE; 73 | 74 | CREATE AGGREGATE range_agg(int8range, boolean) ( 75 | stype = internal, 76 | sfunc = range_agg_transfn, 77 | finalfunc = range_agg_finalfn, 78 | finalfunc_extra 79 | ); 80 | 81 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int8range, boolean, boolean) 82 | RETURNS internal 83 | AS 'range_agg', 'range_agg_transfn' 84 | LANGUAGE c IMMUTABLE; 85 | 86 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int8range, boolean, boolean) 87 | RETURNS int8range[] 88 | AS 'range_agg', 'range_agg_finalfn' 89 | LANGUAGE c IMMUTABLE; 90 | 91 | CREATE AGGREGATE range_agg(int8range, boolean, boolean) ( 92 | stype = internal, 93 | sfunc = range_agg_transfn, 94 | finalfunc = range_agg_finalfn, 95 | finalfunc_extra 96 | ); 97 | 98 | -- numrange 99 | 100 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, numrange, boolean) 101 | RETURNS internal 102 | AS 'range_agg', 'range_agg_transfn' 103 | LANGUAGE c IMMUTABLE; 104 | 105 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, numrange, boolean) 106 | RETURNS numrange[] 107 | AS 'range_agg', 'range_agg_finalfn' 108 | LANGUAGE c IMMUTABLE; 109 | 110 | CREATE AGGREGATE range_agg(numrange, boolean) ( 111 | stype = internal, 112 | sfunc = range_agg_transfn, 113 | finalfunc = range_agg_finalfn, 114 | finalfunc_extra 115 | ); 116 | 117 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, numrange, boolean, boolean) 118 | RETURNS internal 119 | AS 'range_agg', 'range_agg_transfn' 120 | LANGUAGE c IMMUTABLE; 121 | 122 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, numrange, boolean, boolean) 123 | RETURNS numrange[] 124 | AS 'range_agg', 'range_agg_finalfn' 125 | LANGUAGE c IMMUTABLE; 126 | 127 | CREATE AGGREGATE range_agg(numrange, boolean, boolean) ( 128 | stype = internal, 129 | sfunc = range_agg_transfn, 130 | finalfunc = range_agg_finalfn, 131 | finalfunc_extra 132 | ); 133 | 134 | -- tsrange 135 | 136 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tsrange, boolean) 137 | RETURNS internal 138 | AS 'range_agg', 'range_agg_transfn' 139 | LANGUAGE c IMMUTABLE; 140 | 141 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tsrange, boolean) 142 | RETURNS tsrange[] 143 | AS 'range_agg', 'range_agg_finalfn' 144 | LANGUAGE c IMMUTABLE; 145 | 146 | CREATE AGGREGATE range_agg(tsrange, boolean) ( 147 | stype = internal, 148 | sfunc = range_agg_transfn, 149 | finalfunc = range_agg_finalfn, 150 | finalfunc_extra 151 | ); 152 | 153 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tsrange, boolean, boolean) 154 | RETURNS internal 155 | AS 'range_agg', 'range_agg_transfn' 156 | LANGUAGE c IMMUTABLE; 157 | 158 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tsrange, boolean, boolean) 159 | RETURNS tsrange[] 160 | AS 'range_agg', 'range_agg_finalfn' 161 | LANGUAGE c IMMUTABLE; 162 | 163 | CREATE AGGREGATE range_agg(tsrange, boolean, boolean) ( 164 | stype = internal, 165 | sfunc = range_agg_transfn, 166 | finalfunc = range_agg_finalfn, 167 | finalfunc_extra 168 | ); 169 | 170 | -- tstzrange 171 | 172 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tstzrange, boolean) 173 | RETURNS internal 174 | AS 'range_agg', 'range_agg_transfn' 175 | LANGUAGE c IMMUTABLE; 176 | 177 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tstzrange, boolean) 178 | RETURNS tstzrange[] 179 | AS 'range_agg', 'range_agg_finalfn' 180 | LANGUAGE c IMMUTABLE; 181 | 182 | CREATE AGGREGATE range_agg(tstzrange, boolean) ( 183 | stype = internal, 184 | sfunc = range_agg_transfn, 185 | finalfunc = range_agg_finalfn, 186 | finalfunc_extra 187 | ); 188 | 189 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tstzrange, boolean, boolean) 190 | RETURNS internal 191 | AS 'range_agg', 'range_agg_transfn' 192 | LANGUAGE c IMMUTABLE; 193 | 194 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tstzrange, boolean, boolean) 195 | RETURNS tstzrange[] 196 | AS 'range_agg', 'range_agg_finalfn' 197 | LANGUAGE c IMMUTABLE; 198 | 199 | CREATE AGGREGATE range_agg(tstzrange, boolean, boolean) ( 200 | stype = internal, 201 | sfunc = range_agg_transfn, 202 | finalfunc = range_agg_finalfn, 203 | finalfunc_extra 204 | ); 205 | 206 | -- daterange 207 | 208 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, daterange, boolean) 209 | RETURNS internal 210 | AS 'range_agg', 'range_agg_transfn' 211 | LANGUAGE c IMMUTABLE; 212 | 213 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, daterange, boolean) 214 | RETURNS daterange[] 215 | AS 'range_agg', 'range_agg_finalfn' 216 | LANGUAGE c IMMUTABLE; 217 | 218 | CREATE AGGREGATE range_agg(daterange, boolean) ( 219 | stype = internal, 220 | sfunc = range_agg_transfn, 221 | finalfunc = range_agg_finalfn, 222 | finalfunc_extra 223 | ); 224 | 225 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, daterange, boolean, boolean) 226 | RETURNS internal 227 | AS 'range_agg', 'range_agg_transfn' 228 | LANGUAGE c IMMUTABLE; 229 | 230 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, daterange, boolean, boolean) 231 | RETURNS daterange[] 232 | AS 'range_agg', 'range_agg_finalfn' 233 | LANGUAGE c IMMUTABLE; 234 | 235 | CREATE AGGREGATE range_agg(daterange, boolean, boolean) ( 236 | stype = internal, 237 | sfunc = range_agg_transfn, 238 | finalfunc = range_agg_finalfn, 239 | finalfunc_extra 240 | ); 241 | -------------------------------------------------------------------------------- /range_agg--1.2.1.sql: -------------------------------------------------------------------------------- 1 | /* range_agg--1.2.1.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "CREATE EXTENSION range_agg" to load this file. \quit 5 | 6 | 7 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, anyrange) 8 | RETURNS internal 9 | AS 'range_agg', 'range_agg_transfn' 10 | LANGUAGE c IMMUTABLE; 11 | 12 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, anyrange) 13 | RETURNS anyrange 14 | AS 'range_agg', 'range_agg_finalfn' 15 | LANGUAGE c IMMUTABLE; 16 | 17 | CREATE AGGREGATE range_agg(anyrange) ( 18 | stype = internal, 19 | sfunc = range_agg_transfn, 20 | finalfunc = range_agg_finalfn, 21 | finalfunc_extra 22 | ); 23 | 24 | -- 2- and 3-parameter versions must be defined for each range type: 25 | 26 | -- int4range 27 | 28 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int4range, boolean) 29 | RETURNS internal 30 | AS 'range_agg', 'range_agg_transfn' 31 | LANGUAGE c IMMUTABLE; 32 | 33 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int4range, boolean) 34 | RETURNS int4range[] 35 | AS 'range_agg', 'range_agg_finalfn' 36 | LANGUAGE c IMMUTABLE; 37 | 38 | CREATE AGGREGATE range_agg(int4range, boolean) ( 39 | stype = internal, 40 | sfunc = range_agg_transfn, 41 | finalfunc = range_agg_finalfn, 42 | finalfunc_extra 43 | ); 44 | 45 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int4range, boolean, boolean) 46 | RETURNS internal 47 | AS 'range_agg', 'range_agg_transfn' 48 | LANGUAGE c IMMUTABLE; 49 | 50 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int4range, boolean, boolean) 51 | RETURNS int4range[] 52 | AS 'range_agg', 'range_agg_finalfn' 53 | LANGUAGE c IMMUTABLE; 54 | 55 | CREATE AGGREGATE range_agg(int4range, boolean, boolean) ( 56 | stype = internal, 57 | sfunc = range_agg_transfn, 58 | finalfunc = range_agg_finalfn, 59 | finalfunc_extra 60 | ); 61 | 62 | -- int8range 63 | 64 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int8range, boolean) 65 | RETURNS internal 66 | AS 'range_agg', 'range_agg_transfn' 67 | LANGUAGE c IMMUTABLE; 68 | 69 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int8range, boolean) 70 | RETURNS int8range[] 71 | AS 'range_agg', 'range_agg_finalfn' 72 | LANGUAGE c IMMUTABLE; 73 | 74 | CREATE AGGREGATE range_agg(int8range, boolean) ( 75 | stype = internal, 76 | sfunc = range_agg_transfn, 77 | finalfunc = range_agg_finalfn, 78 | finalfunc_extra 79 | ); 80 | 81 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, int8range, boolean, boolean) 82 | RETURNS internal 83 | AS 'range_agg', 'range_agg_transfn' 84 | LANGUAGE c IMMUTABLE; 85 | 86 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, int8range, boolean, boolean) 87 | RETURNS int8range[] 88 | AS 'range_agg', 'range_agg_finalfn' 89 | LANGUAGE c IMMUTABLE; 90 | 91 | CREATE AGGREGATE range_agg(int8range, boolean, boolean) ( 92 | stype = internal, 93 | sfunc = range_agg_transfn, 94 | finalfunc = range_agg_finalfn, 95 | finalfunc_extra 96 | ); 97 | 98 | -- numrange 99 | 100 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, numrange, boolean) 101 | RETURNS internal 102 | AS 'range_agg', 'range_agg_transfn' 103 | LANGUAGE c IMMUTABLE; 104 | 105 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, numrange, boolean) 106 | RETURNS numrange[] 107 | AS 'range_agg', 'range_agg_finalfn' 108 | LANGUAGE c IMMUTABLE; 109 | 110 | CREATE AGGREGATE range_agg(numrange, boolean) ( 111 | stype = internal, 112 | sfunc = range_agg_transfn, 113 | finalfunc = range_agg_finalfn, 114 | finalfunc_extra 115 | ); 116 | 117 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, numrange, boolean, boolean) 118 | RETURNS internal 119 | AS 'range_agg', 'range_agg_transfn' 120 | LANGUAGE c IMMUTABLE; 121 | 122 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, numrange, boolean, boolean) 123 | RETURNS numrange[] 124 | AS 'range_agg', 'range_agg_finalfn' 125 | LANGUAGE c IMMUTABLE; 126 | 127 | CREATE AGGREGATE range_agg(numrange, boolean, boolean) ( 128 | stype = internal, 129 | sfunc = range_agg_transfn, 130 | finalfunc = range_agg_finalfn, 131 | finalfunc_extra 132 | ); 133 | 134 | -- tsrange 135 | 136 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tsrange, boolean) 137 | RETURNS internal 138 | AS 'range_agg', 'range_agg_transfn' 139 | LANGUAGE c IMMUTABLE; 140 | 141 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tsrange, boolean) 142 | RETURNS tsrange[] 143 | AS 'range_agg', 'range_agg_finalfn' 144 | LANGUAGE c IMMUTABLE; 145 | 146 | CREATE AGGREGATE range_agg(tsrange, boolean) ( 147 | stype = internal, 148 | sfunc = range_agg_transfn, 149 | finalfunc = range_agg_finalfn, 150 | finalfunc_extra 151 | ); 152 | 153 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tsrange, boolean, boolean) 154 | RETURNS internal 155 | AS 'range_agg', 'range_agg_transfn' 156 | LANGUAGE c IMMUTABLE; 157 | 158 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tsrange, boolean, boolean) 159 | RETURNS tsrange[] 160 | AS 'range_agg', 'range_agg_finalfn' 161 | LANGUAGE c IMMUTABLE; 162 | 163 | CREATE AGGREGATE range_agg(tsrange, boolean, boolean) ( 164 | stype = internal, 165 | sfunc = range_agg_transfn, 166 | finalfunc = range_agg_finalfn, 167 | finalfunc_extra 168 | ); 169 | 170 | -- tstzrange 171 | 172 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tstzrange, boolean) 173 | RETURNS internal 174 | AS 'range_agg', 'range_agg_transfn' 175 | LANGUAGE c IMMUTABLE; 176 | 177 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tstzrange, boolean) 178 | RETURNS tstzrange[] 179 | AS 'range_agg', 'range_agg_finalfn' 180 | LANGUAGE c IMMUTABLE; 181 | 182 | CREATE AGGREGATE range_agg(tstzrange, boolean) ( 183 | stype = internal, 184 | sfunc = range_agg_transfn, 185 | finalfunc = range_agg_finalfn, 186 | finalfunc_extra 187 | ); 188 | 189 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, tstzrange, boolean, boolean) 190 | RETURNS internal 191 | AS 'range_agg', 'range_agg_transfn' 192 | LANGUAGE c IMMUTABLE; 193 | 194 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, tstzrange, boolean, boolean) 195 | RETURNS tstzrange[] 196 | AS 'range_agg', 'range_agg_finalfn' 197 | LANGUAGE c IMMUTABLE; 198 | 199 | CREATE AGGREGATE range_agg(tstzrange, boolean, boolean) ( 200 | stype = internal, 201 | sfunc = range_agg_transfn, 202 | finalfunc = range_agg_finalfn, 203 | finalfunc_extra 204 | ); 205 | 206 | -- daterange 207 | 208 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, daterange, boolean) 209 | RETURNS internal 210 | AS 'range_agg', 'range_agg_transfn' 211 | LANGUAGE c IMMUTABLE; 212 | 213 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, daterange, boolean) 214 | RETURNS daterange[] 215 | AS 'range_agg', 'range_agg_finalfn' 216 | LANGUAGE c IMMUTABLE; 217 | 218 | CREATE AGGREGATE range_agg(daterange, boolean) ( 219 | stype = internal, 220 | sfunc = range_agg_transfn, 221 | finalfunc = range_agg_finalfn, 222 | finalfunc_extra 223 | ); 224 | 225 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, daterange, boolean, boolean) 226 | RETURNS internal 227 | AS 'range_agg', 'range_agg_transfn' 228 | LANGUAGE c IMMUTABLE; 229 | 230 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, daterange, boolean, boolean) 231 | RETURNS daterange[] 232 | AS 'range_agg', 'range_agg_finalfn' 233 | LANGUAGE c IMMUTABLE; 234 | 235 | CREATE AGGREGATE range_agg(daterange, boolean, boolean) ( 236 | stype = internal, 237 | sfunc = range_agg_transfn, 238 | finalfunc = range_agg_finalfn, 239 | finalfunc_extra 240 | ); 241 | -------------------------------------------------------------------------------- /range_agg.c: -------------------------------------------------------------------------------- 1 | #include 2 | #include 3 | #include 4 | #include 5 | #include 6 | #include 7 | #include 8 | #include 9 | #include 10 | // #if PG_VERSION_NUM >= 90500 11 | // #include 12 | // #endif 13 | #ifndef DatumGetRangeTypeP 14 | #define DatumGetRangeTypeP(X) DatumGetRangeType(X) 15 | #endif 16 | #ifndef RangeTypePGetDatum 17 | #define RangeTypePGetDatum(X) RangeTypeGetDatum(X) 18 | #endif 19 | 20 | PG_MODULE_MAGIC; 21 | 22 | #include "util.c" 23 | static int element_compare(const void *key1, const void *key2, void *arg); 24 | 25 | typedef struct range_agg_state { 26 | ArrayBuildState *inputs; 27 | bool gaps_are_okay; 28 | bool overlaps_are_okay; 29 | } range_agg_state; 30 | 31 | // We can't use the core array_append, 32 | // because we have to capture the second & third parameters 33 | // and put them in the aggregate's running state, 34 | // so that our finalfn can use them. 35 | Datum range_agg_transfn(PG_FUNCTION_ARGS); 36 | PG_FUNCTION_INFO_V1(range_agg_transfn); 37 | 38 | Datum 39 | range_agg_transfn(PG_FUNCTION_ARGS) 40 | { 41 | Oid rangeTypeId; 42 | // Oid rangeBaseTypeId; 43 | MemoryContext aggContext; 44 | range_agg_state *state; 45 | 46 | if (!AggCheckCallContext(fcinfo, &aggContext)) { 47 | elog(ERROR, "range_agg_transfn called in non-aggregate context"); 48 | } 49 | 50 | rangeTypeId = get_fn_expr_argtype(fcinfo->flinfo, 1); 51 | if (!type_is_range(rangeTypeId)) { 52 | ereport(ERROR, (errmsg("range_agg must be called with a range"))); 53 | } 54 | if (PG_ARGISNULL(0)) { 55 | state = MemoryContextAlloc(aggContext, sizeof(range_agg_state)); 56 | state->inputs = initArrayResult(rangeTypeId, aggContext, false); 57 | state->gaps_are_okay = !PG_ARGISNULL(2) && PG_GETARG_BOOL(2); 58 | state->overlaps_are_okay = !PG_ARGISNULL(3) && PG_GETARG_BOOL(3); 59 | } else { 60 | state = (range_agg_state *)PG_GETARG_POINTER(0); 61 | } 62 | 63 | // Might as well just skip NULLs here so the finalfn doesn't have to: 64 | if (!PG_ARGISNULL(1)) { 65 | accumArrayResult(state->inputs, PG_GETARG_DATUM(1), false, rangeTypeId, aggContext); 66 | } 67 | PG_RETURN_POINTER(state); 68 | } 69 | 70 | 71 | Datum range_agg_finalfn(PG_FUNCTION_ARGS); 72 | PG_FUNCTION_INFO_V1(range_agg_finalfn); 73 | 74 | Datum 75 | range_agg_finalfn(PG_FUNCTION_ARGS) 76 | { 77 | MemoryContext aggContext; 78 | 79 | Oid rangeTypeId; 80 | TypeCacheEntry *typcache; 81 | 82 | range_agg_state *state; 83 | ArrayBuildState *inputArray; 84 | int inputLength; 85 | Datum *inputVals; 86 | // bool *inputNulls; 87 | 88 | int i; 89 | RangeType *currentRange; 90 | RangeType *lastRange; 91 | char *r1Str, *r2Str; 92 | 93 | ArrayBuildState *resultContent; 94 | Datum result; 95 | 96 | if (!AggCheckCallContext(fcinfo, &aggContext)) { 97 | elog(ERROR, "range_agg_finalfn called in non-aggregate context"); 98 | } 99 | 100 | state = PG_ARGISNULL(0) ? NULL : (range_agg_state *)PG_GETARG_POINTER(0); 101 | if (state == NULL) PG_RETURN_NULL(); 102 | inputArray = state->inputs; 103 | inputVals = inputArray->dvalues; 104 | // inputNulls = inputArray->dnulls; 105 | inputLength = inputArray->nelems; 106 | rangeTypeId = inputArray->element_type; 107 | 108 | typcache = range_get_typcache(fcinfo, rangeTypeId); 109 | if (inputLength == 0) PG_RETURN_NULL(); 110 | qsort_arg(inputVals, inputLength, sizeof(Datum), element_compare, typcache); 111 | 112 | resultContent = initArrayResult(rangeTypeId, aggContext, false); 113 | lastRange = DatumGetRangeTypeP(inputVals[0]); 114 | for (i = 1; i < inputLength; i++) { 115 | // Assert(inputNulls[i]); 116 | currentRange = DatumGetRangeTypeP(inputVals[i]); 117 | // N.B. range_adjacent_internal gives true 118 | // if *either* A meets B OR B meets A, 119 | // which is not quite what we want, 120 | // but we rely on the sorting above to rule out B meets A ever happening. 121 | if (range_adjacent_internal(typcache, lastRange, currentRange)) { 122 | lastRange = range_union_internal(typcache, lastRange, currentRange, false); 123 | 124 | } else if (range_before_internal(typcache, lastRange, currentRange)) { 125 | if (!state->gaps_are_okay) { 126 | r1Str = "lastRange"; r2Str = "currentRange"; 127 | // TODO: Why is this segfaulting?: 128 | // This is why: https://www.postgresql.org/message-id/CA%2BrenyUeS3vBGxur6-eZ5YCy_XKK7sFRG77DJezSMxrpeJ-9ag%40mail.gmail.com 129 | // r1Str = DatumGetCString(DirectFunctionCall1(range_out, RangeTypePGetDatum(lastRange))); 130 | // r2Str = DatumGetCString(DirectFunctionCall1(range_out, RangeTypePGetDatum(currentRange))); 131 | ereport(ERROR, (errmsg("range_agg: gap detected between %s and %s", r1Str, r2Str))); 132 | } 133 | accumArrayResult(resultContent, RangeTypePGetDatum(lastRange), false, rangeTypeId, aggContext); 134 | lastRange = currentRange; 135 | 136 | } else { // they must overlap 137 | if (!state->overlaps_are_okay) { 138 | r1Str = "lastRange"; r2Str = "currentRange"; 139 | // TODO: Why is this segfaulting?: 140 | // This is why: https://www.postgresql.org/message-id/CA%2BrenyUeS3vBGxur6-eZ5YCy_XKK7sFRG77DJezSMxrpeJ-9ag%40mail.gmail.com 141 | // r1Str = DatumGetCString(DirectFunctionCall1(range_out, RangeTypePGetDatum(lastRange))); 142 | // r2Str = DatumGetCString(DirectFunctionCall1(range_out, RangeTypePGetDatum(currentRange))); 143 | ereport(ERROR, (errmsg("range_agg: overlap detected between %s and %s", r1Str, r2Str))); 144 | } 145 | lastRange = range_union_internal(typcache, lastRange, currentRange, false); 146 | } 147 | } 148 | accumArrayResult(resultContent, RangeTypePGetDatum(lastRange), false, rangeTypeId, aggContext); 149 | 150 | if (type_is_array(get_fn_expr_rettype(fcinfo->flinfo))) { 151 | result = makeArrayResult(resultContent, CurrentMemoryContext); 152 | PG_RETURN_DATUM(result); 153 | } else { 154 | PG_RETURN_DATUM(RangeTypePGetDatum(lastRange)); 155 | } 156 | } 157 | 158 | static int element_compare(const void *key1, const void *key2, void *arg) { 159 | Datum *d1 = (Datum *)key1; 160 | Datum *d2 = (Datum *)key2; 161 | RangeType *r1 = DatumGetRangeTypeP(*d1); 162 | RangeType *r2 = DatumGetRangeTypeP(*d2); 163 | TypeCacheEntry *typcache = (TypeCacheEntry *) arg; 164 | RangeBound lower1, lower2; 165 | RangeBound upper1, upper2; 166 | bool empty1, empty2; 167 | int cmp; 168 | 169 | range_deserialize(typcache, r1, &lower1, &upper1, &empty1); 170 | range_deserialize(typcache, r2, &lower2, &upper2, &empty2); 171 | 172 | if (empty1 && empty2) cmp = 0; 173 | else if (empty1) cmp = -1; 174 | else if (empty2) cmp = 1; 175 | else { 176 | cmp = range_cmp_bounds(typcache, &lower1, &lower2); 177 | if (cmp == 0) cmp = range_cmp_bounds(typcache, &upper1, &upper2); 178 | } 179 | 180 | return cmp; 181 | } 182 | -------------------------------------------------------------------------------- /range_agg.control: -------------------------------------------------------------------------------- 1 | comment = 'Merge adjacent/overlapping ranges' 2 | default_version = '1.2.1' 3 | module_pathname = '$libdir/range_agg' 4 | relocatable = true 5 | -------------------------------------------------------------------------------- /sql/inetrange_test.sql: -------------------------------------------------------------------------------- 1 | -- Verify that it works on custom range types: 2 | 3 | CREATE OR REPLACE FUNCTION inet_diff(x inet, y inet) 4 | RETURNS DOUBLE PRECISION AS 5 | $$ 6 | DECLARE 7 | BEGIN 8 | RETURN x - y; 9 | END; 10 | $$ 11 | LANGUAGE 'plpgsql' STRICT IMMUTABLE; 12 | 13 | CREATE TYPE inetrange AS RANGE ( 14 | subtype = inet, 15 | subtype_diff = inet_diff 16 | ); 17 | 18 | SELECT range_agg(r) 19 | FROM (VALUES 20 | (inetrange('1.2.3.0', '1.2.4.0', '[)')), 21 | (inetrange('1.2.4.0', '1.2.5.0', '[)')) 22 | ) t(r); 23 | 24 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, inetrange, boolean) 25 | RETURNS internal 26 | AS 'range_agg', 'range_agg_transfn' 27 | LANGUAGE c IMMUTABLE; 28 | 29 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, inetrange, boolean) 30 | RETURNS inetrange[] 31 | AS 'range_agg', 'range_agg_finalfn' 32 | LANGUAGE c IMMUTABLE; 33 | 34 | CREATE AGGREGATE range_agg(inetrange, boolean) ( 35 | stype = internal, 36 | sfunc = range_agg_transfn, 37 | finalfunc = range_agg_finalfn, 38 | finalfunc_extra 39 | ); 40 | 41 | SELECT range_agg(r, true) 42 | FROM (VALUES 43 | (inetrange('1.2.3.0', '1.2.3.128', '[)')), 44 | (inetrange('1.2.4.0', '1.2.5.0', '[)')) 45 | ) t(r); 46 | 47 | CREATE OR REPLACE FUNCTION range_agg_transfn(internal, inetrange, boolean, boolean) 48 | RETURNS internal 49 | AS 'range_agg', 'range_agg_transfn' 50 | LANGUAGE c IMMUTABLE; 51 | 52 | CREATE OR REPLACE FUNCTION range_agg_finalfn(internal, inetrange, boolean, boolean) 53 | RETURNS inetrange[] 54 | AS 'range_agg', 'range_agg_finalfn' 55 | LANGUAGE c IMMUTABLE; 56 | 57 | CREATE AGGREGATE range_agg(inetrange, boolean, boolean) ( 58 | stype = internal, 59 | sfunc = range_agg_transfn, 60 | finalfunc = range_agg_finalfn, 61 | finalfunc_extra 62 | ); 63 | 64 | SELECT range_agg(r, true, true) 65 | FROM (VALUES 66 | (inetrange('1.2.3.0', '1.2.3.128', '[)')), 67 | (inetrange('1.2.4.0', '1.2.5.0', '[)')) 68 | ) t(r); 69 | 70 | -------------------------------------------------------------------------------- /sql/init.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION range_agg; 2 | 3 | CREATE TABLE reservations ( 4 | room_id INTEGER NOT NULL, 5 | booked_during daterange 6 | ); 7 | 8 | INSERT INTO reservations 9 | (room_id, booked_during) 10 | VALUES 11 | -- 1: has a meets and a gap 12 | (1, daterange('2018-07-01', '2018-07-07')), 13 | (1, daterange('2018-07-07', '2018-07-14')), 14 | (1, daterange('2018-07-20', '2018-07-22')), 15 | -- 2: just a single row 16 | (2, daterange('2018-07-01', '2018-07-03')), 17 | -- 3: one null range 18 | (3, NULL), 19 | -- 4: two null ranges 20 | (4, NULL), 21 | (4, NULL), 22 | -- 5: a null range and a non-null range 23 | (5, NULL), 24 | (5, daterange('2018-07-01', '2018-07-03')), 25 | -- 6: has overlap 26 | (6, daterange('2018-07-01', '2018-07-07')), 27 | (6, daterange('2018-07-05', '2018-07-10')), 28 | -- 7: two ranges that meet: no gap or overlap 29 | (7, daterange('2018-07-01', '2018-07-07')), 30 | (7, daterange('2018-07-07', '2018-07-14')) 31 | ; 32 | -------------------------------------------------------------------------------- /sql/range_agg_1_test.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- 3 | -- Forbidding gaps and overlaps: 4 | -- 5 | -- 6 | SELECT room_id, range_agg(booked_during) 7 | FROM reservations 8 | WHERE room_id = 1 9 | GROUP BY room_id 10 | ORDER BY room_id; 11 | 12 | SELECT room_id, range_agg(booked_during) 13 | FROM reservations 14 | WHERE room_id = 6 15 | GROUP BY room_id 16 | ORDER BY room_id; 17 | 18 | SELECT room_id, range_agg(booked_during) 19 | FROM reservations 20 | WHERE room_id NOT IN (1, 6) 21 | GROUP BY room_id 22 | ORDER BY room_id; 23 | -- 24 | -- 25 | -- Obeying discrete base types: 26 | -- 27 | -- 28 | SELECT range_agg(r) 29 | FROM (VALUES 30 | (int4range( 0, 9, '[]')), 31 | (int4range(10, 19, '[]')) 32 | ) t(r); 33 | -------------------------------------------------------------------------------- /sql/range_agg_2_test.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- 3 | -- Forbidding gaps (and overlaps): 4 | -- 5 | -- 6 | SELECT room_id, range_agg(booked_during, false) 7 | FROM reservations 8 | WHERE room_id = 1 9 | GROUP BY room_id; 10 | 11 | SELECT room_id, range_agg(booked_during, false) 12 | FROM reservations 13 | WHERE room_id = 6 14 | GROUP BY room_id; 15 | 16 | SELECT room_id, range_agg(booked_during, false) 17 | FROM reservations 18 | WHERE room_id NOT IN (1, 6) 19 | GROUP BY room_id; 20 | -- 21 | -- 22 | -- Permitting gaps (but forbidding overlaps): 23 | -- 24 | -- 25 | SELECT room_id, range_agg(booked_during, true) 26 | FROM reservations 27 | WHERE room_id = 1 28 | GROUP BY room_id; 29 | 30 | SELECT room_id, range_agg(booked_during, true) 31 | FROM reservations 32 | WHERE room_id = 6 33 | GROUP BY room_id; 34 | 35 | SELECT room_id, range_agg(booked_during, true) 36 | FROM reservations 37 | WHERE room_id NOT IN (1, 6) 38 | GROUP BY room_id; 39 | -------------------------------------------------------------------------------- /sql/range_agg_3_test.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- 3 | -- Forbidding gaps and overlaps: 4 | -- 5 | -- 6 | SELECT room_id, range_agg(booked_during, false, false) 7 | FROM reservations 8 | WHERE room_id = 1 9 | GROUP BY room_id; 10 | 11 | SELECT room_id, range_agg(booked_during, false, false) 12 | FROM reservations 13 | WHERE room_id = 6 14 | GROUP BY room_id; 15 | 16 | SELECT room_id, range_agg(booked_during, false, false) 17 | FROM reservations 18 | WHERE room_id NOT IN (1, 6) 19 | GROUP BY room_id; 20 | -- 21 | -- 22 | -- Forbidding gaps but permitting overlaps 23 | -- 24 | -- 25 | SELECT room_id, range_agg(booked_during, false, true) 26 | FROM reservations 27 | WHERE room_id = 1 28 | GROUP BY room_id; 29 | 30 | SELECT room_id, range_agg(booked_during, false, true) 31 | FROM reservations 32 | WHERE room_id = 6 33 | GROUP BY room_id; 34 | 35 | SELECT room_id, range_agg(booked_during, false, true) 36 | FROM reservations 37 | WHERE room_id NOT IN (1, 6) 38 | GROUP BY room_id; 39 | -- 40 | -- 41 | -- Permitting gaps but forbidding overlaps 42 | -- 43 | -- 44 | SELECT room_id, range_agg(booked_during, true, false) 45 | FROM reservations 46 | WHERE room_id = 1 47 | GROUP BY room_id; 48 | 49 | SELECT room_id, range_agg(booked_during, true, false) 50 | FROM reservations 51 | WHERE room_id = 6 52 | GROUP BY room_id; 53 | 54 | SELECT room_id, range_agg(booked_during, true, false) 55 | FROM reservations 56 | WHERE room_id NOT IN (1, 6) 57 | GROUP BY room_id; 58 | -- 59 | -- 60 | -- Permitting gaps and overlaps: 61 | -- 62 | -- 63 | SELECT room_id, range_agg(booked_during, true, true) 64 | FROM reservations 65 | WHERE room_id = 1 66 | GROUP BY room_id; 67 | 68 | SELECT room_id, range_agg(booked_during, true, true) 69 | FROM reservations 70 | WHERE room_id = 6 71 | GROUP BY room_id; 72 | 73 | SELECT room_id, range_agg(booked_during, true, true) 74 | FROM reservations 75 | WHERE room_id NOT IN (1, 6) 76 | GROUP BY room_id; 77 | -- 78 | -- 79 | -- Obeying discrete base types: 80 | -- 81 | -- 82 | SELECT range_agg(r, false, false) 83 | FROM (VALUES 84 | (int4range( 0, 5, '[]')), 85 | (int4range( 7, 9, '[]')) 86 | ) t(r); 87 | 88 | SELECT range_agg(r, false, false) 89 | FROM (VALUES 90 | (int4range( 0, 5, '[]')), 91 | (int4range( 5, 9, '[]')) 92 | ) t(r); 93 | 94 | SELECT range_agg(r, true, true) 95 | FROM (VALUES 96 | (int4range( 0, 9, '[]')), 97 | (int4range(10, 15, '[]')), 98 | (int4range(20, 26, '[]')), 99 | (int4range(26, 29, '[]')) 100 | ) t(r); 101 | -------------------------------------------------------------------------------- /sql/with_unnest.sql: -------------------------------------------------------------------------------- 1 | -- It combines with UNNEST 2 | -- to implement the temporal database "coalesce" function 3 | -- (see Snodgrass 6.5.2): 4 | SELECT room_id, t2.booked_during 5 | FROM ( 6 | SELECT room_id, range_agg(booked_during, true, true) AS booked_during 7 | FROM reservations 8 | GROUP BY room_id 9 | ) AS t1, 10 | UNNEST(t1.booked_during) AS t2(booked_during) 11 | ORDER BY room_id, booked_during 12 | ; 13 | -------------------------------------------------------------------------------- /util.c: -------------------------------------------------------------------------------- 1 | /* 2 | * Lots of stuff copied from backend/utils/adt/rangetypes.c 3 | */ 4 | 5 | static RangeType * 6 | range_union_internal(TypeCacheEntry *typcache, RangeType *r1, RangeType *r2, 7 | bool strict); 8 | 9 | /* 10 | * Set union. If strict is true, it is an error that the two input ranges 11 | * are not adjacent or overlapping. 12 | */ 13 | static RangeType * 14 | range_union_internal(TypeCacheEntry *typcache, RangeType *r1, RangeType *r2, 15 | bool strict) 16 | { 17 | RangeBound lower1, 18 | lower2; 19 | RangeBound upper1, 20 | upper2; 21 | bool empty1, 22 | empty2; 23 | RangeBound *result_lower; 24 | RangeBound *result_upper; 25 | 26 | /* Different types should be prevented by ANYRANGE matching rules */ 27 | if (RangeTypeGetOid(r1) != RangeTypeGetOid(r2)) 28 | elog(ERROR, "range types do not match"); 29 | 30 | range_deserialize(typcache, r1, &lower1, &upper1, &empty1); 31 | range_deserialize(typcache, r2, &lower2, &upper2, &empty2); 32 | 33 | /* if either is empty, the other is the correct answer */ 34 | if (empty1) 35 | return r2; 36 | if (empty2) 37 | return r1; 38 | 39 | if (strict && 40 | !DatumGetBool(range_overlaps_internal(typcache, r1, r2)) && 41 | !DatumGetBool(range_adjacent_internal(typcache, r1, r2))) 42 | ereport(ERROR, 43 | (errcode(ERRCODE_DATA_EXCEPTION), 44 | errmsg("result of range union would not be contiguous"))); 45 | 46 | if (range_cmp_bounds(typcache, &lower1, &lower2) < 0) 47 | result_lower = &lower1; 48 | else 49 | result_lower = &lower2; 50 | 51 | if (range_cmp_bounds(typcache, &upper1, &upper2) > 0) 52 | result_upper = &upper1; 53 | else 54 | result_upper = &upper2; 55 | 56 | return make_range(typcache, result_lower, result_upper, false); 57 | } 58 | 59 | --------------------------------------------------------------------------------