├── .gitignore ├── LICENSE ├── META.json ├── Makefile ├── README.md ├── pgfaceting.control ├── sql └── pgfaceting--0.2.0.sql └── test ├── expected ├── base.out └── error_checks.out └── sql ├── base.sql └── error_checks.sql /.gitignore: -------------------------------------------------------------------------------- 1 | results 2 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright 2022 Ants Aasma 2 | 3 | Redistribution and use in source and binary forms, with or without modification, are permitted provided that the following conditions are met: 4 | 5 | 1. Redistributions of source code must retain the above copyright notice, this list of conditions and the following disclaimer. 6 | 7 | 2. Redistributions in binary form must reproduce the above copyright notice, this list of conditions and the following disclaimer in the documentation and/or other materials provided with the distribution. 8 | 9 | 3. Neither the name of the copyright holder nor the names of its contributors may be used to endorse or promote products derived from this software without specific prior written permission. 10 | 11 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 12 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "pgfaceting", 3 | "abstract": "Quickly calculate facet counts using inverted index built with roaring bitmaps.", 4 | "description": "", 5 | "version": "0.2.0", 6 | "maintainer": [ 7 | "Ants Aasma " 8 | ], 9 | "license": "bsd", 10 | "prereqs": { 11 | "runtime": { 12 | "requires": { 13 | "PostgreSQL": "11.0" 14 | } 15 | } 16 | }, 17 | "provides": { 18 | "pgfaceting": { 19 | "file": "sql/pgfaceting--0.1.0.sql", 20 | "docfile" : "README.md", 21 | "version": "0.2.0" 22 | } 23 | }, 24 | "resources": { 25 | "repository": { 26 | "url": "https://github.com/cybertec-postgresql/pgfaceting.git", 27 | "web": "https://github.com/cybertec-postgresql/pgfaceting", 28 | "type": "git" 29 | } 30 | }, 31 | "tags" : ["count", "aggregate", "performance", "bitmap"], 32 | "meta-spec": { 33 | "version": "1.0.0", 34 | "url": "http://pgxn.org/meta/spec.txt" 35 | }, 36 | "release_status" : "unstable" 37 | } 38 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = pgfaceting 2 | DATA = sql/pgfaceting--0.2.0.sql 3 | 4 | TESTS = $(wildcard test/sql/*.sql) 5 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 6 | REGRESS_OPTS = --inputdir=test 7 | 8 | PG_CONFIG = pg_config 9 | PGXS := $(shell $(PG_CONFIG) --pgxs) 10 | include $(PGXS) 11 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # pgfaceting 2 | 3 | PostgreSQL extension to quickly calculate facet counts using inverted index built with 4 | [roaring bitmaps](https://roaringbitmap.org/). Requires 5 | [pg_roaringbitmap](https://github.com/ChenHuajun/pg_roaringbitmap) to be installed. 6 | 7 | Faceting means counting number occurrences of each value in a result set for a set of attributes. Typical example of 8 | faceting is a web shop where you can see how many items are remaining after filtering your search by red, green or 9 | blue, and how many when filtering by size small, medium or large. 10 | 11 | Work on this project has been sponsored by [Xenit](https://xenit.eu/). 12 | 13 | ## Build and install 14 | 15 | make install 16 | make installcheck 17 | psql -c "create extension roaringbitmap" -c "create extension pgfaceting" 18 | 19 | ## Usage 20 | 21 | pgfaceting creates and maintains two extra tables for your main table. `tbl_facets` contains for each facet and 22 | value combination a list of id values for rows containing that combination. The list is stored as a roaring 23 | bitmap for quick intersection and cardinality operations. Because updating this list is a heavy operation any changes 24 | to the main table get stored in `tbl_facets_deltas` as a combination of facet, value, id and +1 or -1 depending 25 | on the kind of update. A periodic maintenance job is responsible for merging deltas into the main facets table. 26 | 27 | Currently only 32bit integer id columns are supported. When pg\_roaringbitmap adds support for 64bit bitmaps 28 | then int8 and possibly ctid could be supported. 29 | 30 | ### Adding faceting to a table 31 | 32 | SELECT faceting.add_faceting_to_table( 33 | 'documents', 34 | key => 'id', 35 | facets => array[ 36 | faceting.datetrunc_facet('created', 'month'), 37 | faceting.datetrunc_facet('finished', 'month'), 38 | faceting.plain_facet('category_id'), 39 | faceting.plain_facet('type'), 40 | faceting.bucket_facet('size', buckets => array[0,1000,5000,10000,50000,100000,500000]) 41 | ] 42 | ); 43 | 44 | The `add_faceting_to_table()` adds the facets tables and populates the contents. It takes an array of facets 45 | to extract from each row. 46 | 47 | * `plain_facet(col name)` - Takes the column value as is as the facet value. 48 | * `datetrunc_facet(col name, precision text)` - Applies a date\_trunc function on a column to get the facet value. 49 | Useful for timebucketing (yearly, monthly, etc.) 50 | * `bucket_facet(col name, buckets anyarray)` - Assigns a continuous variable (price, weight, etc.) to a set of buckets 51 | and stores the index of the chosen bucket as the facet value. 52 | 53 | For merging changes create a periodic job that runs: 54 | 55 | CALL faceting.run_maintenance(); 56 | 57 | This will run delta merging on all faceted tables. There is also a function for maintaining a single table: 58 | 59 | SELECT faceting.merge_deltas('documents'::regclass); 60 | 61 | ### Querying facets 62 | 63 | Getting top 10 values for each kind of facet: 64 | 65 | SELECT * FROM faceting.top_values('documents'::regclass, n => 10); 66 | 67 | We can also filter by some facets and get the results of other facets: 68 | 69 | SELECT * FROM faceting.count_results('documents'::regclass, 70 | filters => array[row('category_id', '24'), 71 | row('type', 'image/jpeg')]::faceting.facet_filter[]); 72 | 73 | For advanced usage the inverted index tables can be accessed directly. 74 | 75 | WITH lookup AS ( 76 | SELECT id >> 20 AS chunk_id, rb_build_agg(id) postinglist 77 | FROM documents 78 | WHERE ... 79 | ) 80 | SELECT facet_id, facet_value, sum(rb_and_cardinality(flt.postinglist, fct.postinglist)) 81 | FROM lookup flt JOIN documents_facets USING (chunk_id) 82 | GROUP BY 1, 2; 83 | 84 | ### How fast is it 85 | 86 | Calculating facets for 61% of rows in 100M row table: 87 | 88 | -- 24 vcore parallel seq scan 89 | postgres=# SELECT facet_name, count(distinct facet_value), sum(cardinality) 90 | FROM (SELECT facet_name, facet_value, COUNT(*) cardinality 91 | FROM test2.documents d, LATERAL (VALUES 92 | ('created', date_trunc('month', created)::text), 93 | ('finished', date_trunc('month', finished)::text), 94 | ('type', type::text), 95 | ('size', width_bucket(size, array[0,1000,5000,10000,50000,100000,500000])::text) 96 | ) t(facet_name, facet_value) 97 | WHERE category_id = 24 98 | GROUP BY 1, 2) count_results 99 | GROUP BY 1; 100 | facet_name | count | sum 101 | ------------+-------+---------- 102 | created | 154 | 60812252 103 | finished | 154 | 60812252 104 | size | 7 | 60812252 105 | type | 8 | 60812252 106 | (4 rows) 107 | 108 | Time: 18440.061 ms (00:18.440) 109 | 110 | -- Single core only 111 | postgres=# SET max_parallel_workers_per_gather = 0; 112 | SET 113 | Time: 0.206 ms 114 | postgres=# SELECT facet_name, count(distinct facet_value), sum(cardinality) 115 | FROM (SELECT facet_name, facet_value, COUNT(*) cardinality 116 | FROM test2.documents d, LATERAL (VALUES 117 | ('created', date_trunc('month', created)::text), 118 | ('finished', date_trunc('month', finished)::text), 119 | ('type', type::text), 120 | ('size', width_bucket(size, array[0,1000,5000,10000,50000,100000,500000])::text) 121 | ) t(facet_name, facet_value) 122 | WHERE category_id = 24 123 | GROUP BY 1, 2) count_results 124 | GROUP BY 1; 125 | facet_name | count | sum 126 | ------------+-------+---------- 127 | created | 154 | 60812252 128 | finished | 154 | 60812252 129 | size | 7 | 60812252 130 | type | 8 | 60812252 131 | (4 rows) 132 | 133 | Time: 222019.758 ms (03:42.020) 134 | 135 | -- Using facets index 136 | postgres=# SELECT facet_name, count(distinct facet_value), sum(cardinality) 137 | FROM faceting.count_results('documents'::regclass, 138 | filters => array[row('category_id', 24)]::faceting.facet_filter[]) 139 | GROUP BY 1; 140 | facet_name | count | sum 141 | ------------+-------+---------- 142 | created | 154 | 60812252 143 | finished | 154 | 60812252 144 | size | 7 | 60812252 145 | type | 8 | 60812252 146 | (4 rows) 147 | 148 | Time: 155.228 ms 149 | -------------------------------------------------------------------------------- /pgfaceting.control: -------------------------------------------------------------------------------- 1 | # faceting extension 2 | comment = 'fast faceting queries using an inverted index' 3 | default_version = '0.2.0' 4 | relocatable = false 5 | schema = 'faceting' 6 | requires = 'roaringbitmap' 7 | superuser = false 8 | -------------------------------------------------------------------------------- /sql/pgfaceting--0.2.0.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION faceting._identifier_append(ident text, append text) RETURNS text 2 | LANGUAGE SQL 3 | AS $$ 4 | SELECT CASE WHEN right(ident, 1) = '"' THEN 5 | substr(ident, 1, length(ident) - 1) || append || '"' 6 | ELSE ident || append END; 7 | $$; 8 | 9 | CREATE FUNCTION faceting._name_only(ident text) RETURNS text 10 | LANGUAGE SQL 11 | AS $$ 12 | SELECT regexp_replace(ident, '^([^"]*|"([^\"]|\\")*")\.', ''); 13 | $$; 14 | 15 | CREATE FUNCTION faceting._qualified(schemaname text, tablename text) RETURNS text 16 | LANGUAGE SQL 17 | AS $$ 18 | SELECT format('%s.%s', quote_ident(schemaname), quote_ident(tablename)); 19 | $$; 20 | 21 | CREATE TABLE faceting.faceted_table ( 22 | table_id oid primary key, 23 | schemaname text, 24 | tablename text, 25 | facets_table text, 26 | delta_table text, 27 | key name, 28 | key_type text, 29 | chunk_bits int 30 | ); 31 | 32 | SELECT pg_catalog.pg_extension_config_dump('faceting.faceted_table', ''); 33 | 34 | CREATE TABLE faceting.facet_definition ( 35 | table_id oid NOT NULL REFERENCES faceted_table (table_id), 36 | facet_id int NOT NULL, 37 | facet_name text NOT NULL, 38 | facet_type text NOT NULL, 39 | base_column name, 40 | params jsonb, 41 | is_multi bool not null, 42 | supports_delta bool not null, 43 | PRIMARY KEY (table_id, facet_id) 44 | ); 45 | 46 | CREATE UNIQUE INDEX facet_definition_uniq_name ON faceting.facet_definition (table_id, facet_name); 47 | 48 | SELECT pg_catalog.pg_extension_config_dump('faceting.facet_definition', ''); 49 | 50 | CREATE FUNCTION faceting.add_faceting_to_table(p_table regclass, 51 | key name, 52 | facets facet_definition[], 53 | chunk_bits int = 20, 54 | keep_deltas bool = true, 55 | populate bool = true) 56 | RETURNS void 57 | LANGUAGE plpgsql 58 | AS $$ 59 | DECLARE 60 | schemaname text; 61 | tablename text; 62 | facet_tablename text; 63 | delta_tablename text; 64 | v_table_id int; 65 | v_facet_defs faceting.facet_definition[]; 66 | key_type text; 67 | BEGIN 68 | SELECT relname, nspname INTO tablename, schemaname 69 | FROM pg_class c JOIN pg_namespace n ON relnamespace = n.oid WHERE c.oid = p_table::oid; 70 | IF NOT FOUND THEN 71 | RAISE EXCEPTION 'Cannot find table %', p_table; 72 | END IF; 73 | 74 | -- Can't make us of highest bit of int4 because don't want to dealt with negative values 75 | IF chunk_bits NOT BETWEEN 1 AND 31 THEN 76 | RAISE EXCEPTION 'Invalid number of bits per chunk: %', chunk_bits; 77 | END IF; 78 | 79 | -- Default chunking size is 1Mi. 80 | /* TODO: namespace qualify to be in the same schema as parent table */ 81 | facet_tablename := faceting._identifier_append(tablename, '_facets'); 82 | delta_tablename := faceting._identifier_append(tablename, '_facets_deltas'); 83 | 84 | SELECT t.typname INTO key_type FROM pg_attribute a JOIN pg_type t ON t.oid = a.atttypid 85 | WHERE attrelid = p_table::oid AND attname = key; 86 | IF NOT FOUND THEN 87 | RAISE EXCEPTION 'Key column % not found in %s.%s', key, schemaname, tablename; 88 | ELSIF key_type NOT IN ('int2', 'int4', 'int8') THEN 89 | RAISE EXCEPTION 'Key column type % is not supported.', key_type; 90 | END IF; 91 | 92 | INSERT INTO faceting.faceted_table (table_id, schemaname, tablename, facets_table, delta_table, key, 93 | key_type, chunk_bits) 94 | VALUES (p_table::oid, schemaname, tablename, facet_tablename, CASE WHEN keep_deltas THEN delta_tablename END, key, 95 | key_type, chunk_bits) 96 | RETURNING table_id INTO v_table_id; 97 | 98 | WITH stored_definitions AS ( 99 | INSERT INTO faceting.facet_definition (table_id, facet_id, facet_name, facet_type, base_column, params, is_multi, supports_delta) 100 | SELECT v_table_id, assigned_id, facet_name, facet_type, base_column, params, is_multi, supports_delta 101 | FROM UNNEST(facets) WITH ORDINALITY AS x(_, _, facet_name, facet_type, base_column, params, is_multi, supports_delta, assigned_id) 102 | RETURNING *) 103 | SELECT array_agg(f) INTO v_facet_defs FROM stored_definitions f; 104 | 105 | /* TODO: allow NULLs to be stored for PG v15+ */ 106 | -- Create facet storage 107 | EXECUTE format($sql$ 108 | CREATE TABLE %s ( 109 | facet_id int4 not null, 110 | chunk_id int4 not null, 111 | facet_value text collate "C" null, 112 | postinglist roaringbitmap not null, 113 | primary key (facet_id, facet_value, chunk_id) 114 | ); 115 | ALTER TABLE %s SET (toast_tuple_target = 8160);$sql$, 116 | faceting._qualified(schemaname, facet_tablename), 117 | faceting._qualified(schemaname, facet_tablename)); 118 | 119 | IF keep_deltas THEN 120 | -- Delta storage 121 | EXECUTE format($sql$ 122 | CREATE TABLE %s ( 123 | facet_id int4 not null, 124 | facet_value text collate "C" null, 125 | posting %s not null, 126 | delta int2, 127 | primary key (facet_id, facet_value, posting) 128 | ); 129 | $sql$, faceting._qualified(schemaname, delta_tablename), key_type); 130 | 131 | PERFORM faceting.create_delta_trigger(v_table_id); 132 | END IF; 133 | 134 | IF populate THEN 135 | PERFORM faceting.populate_facets(v_table_id, false); 136 | END IF; 137 | END; 138 | $$; 139 | 140 | CREATE FUNCTION faceting._get_values_clause(fdef facet_definition, extra_cols text, table_alias text) 141 | RETURNS text 142 | LANGUAGE plpgsql 143 | AS $$ 144 | DECLARE 145 | result text; 146 | BEGIN 147 | EXECUTE format('SELECT faceting.%s_facet_values($1, $2, $3)', fdef.facet_type) INTO result 148 | USING fdef, extra_cols, table_alias; 149 | RETURN result; 150 | END; 151 | $$; 152 | 153 | CREATE FUNCTION faceting._get_subquery_clause(fdef facet_definition, extra_cols text, table_alias text) 154 | RETURNS text 155 | LANGUAGE plpgsql 156 | AS $$ 157 | DECLARE 158 | result text; 159 | BEGIN 160 | EXECUTE format('SELECT faceting.%s_facet_subquery($1, $2, $3)', fdef.facet_type) INTO result 161 | USING fdef, extra_cols, table_alias; 162 | RETURN result; 163 | END; 164 | $$; 165 | 166 | CREATE FUNCTION faceting.add_facets(p_table regclass, 167 | facets facet_definition[], 168 | populate bool = true) 169 | RETURNS SETOF int4 170 | LANGUAGE plpgsql 171 | AS $$ 172 | DECLARE 173 | v_table_id oid; 174 | tdef faceting.faceted_table; 175 | highest_facet_id int4; 176 | v_facet_names text[]; 177 | v_facet_ids int4[]; 178 | BEGIN 179 | v_table_id := p_table::oid; 180 | SELECT t.* INTO tdef FROM faceting.faceted_table t WHERE t.table_id = v_table_id; 181 | IF NOT FOUND THEN 182 | RAISE EXCEPTION 'Table % is not faceted', p_table; 183 | END IF; 184 | SELECT MAX(facet_id) INTO highest_facet_id FROM faceting.facet_definition WHERE table_id = v_table_id; 185 | 186 | WITH stored_definitions AS ( 187 | INSERT INTO faceting.facet_definition (table_id, facet_id, facet_name, facet_type, base_column, params, is_multi, supports_delta) 188 | SELECT v_table_id, highest_facet_id + assigned_id, facet_name, facet_type, base_column, params, is_multi, supports_delta 189 | FROM UNNEST(facets) WITH ORDINALITY AS x(_, _, facet_name, facet_type, base_column, params, is_multi, supports_delta, assigned_id) 190 | RETURNING *) 191 | SELECT array_agg(f.facet_name), array_agg(f.facet_id) INTO v_facet_names, v_facet_ids FROM stored_definitions f; 192 | 193 | IF tdef.delta_table IS NOT NULL THEN 194 | PERFORM faceting.create_delta_trigger(v_table_id); 195 | END IF; 196 | 197 | IF populate THEN 198 | PERFORM faceting.populate_facets(v_table_id, false, facets := v_facet_names); 199 | END IF; 200 | RETURN QUERY SELECT unnest(v_facet_ids); 201 | END; 202 | $$; 203 | 204 | CREATE FUNCTION faceting.drop_facets(p_table regclass, 205 | facets text[]) 206 | RETURNS SETOF text 207 | LANGUAGE plpgsql 208 | AS $$ 209 | DECLARE 210 | v_table_id oid; 211 | tdef faceting.faceted_table; 212 | v_dropped_names text[]; 213 | v_dropped_ids int4[]; 214 | BEGIN 215 | v_table_id := p_table::oid; 216 | SELECT t.* INTO tdef FROM faceting.faceted_table t WHERE t.table_id = v_table_id; 217 | IF NOT FOUND THEN 218 | RAISE EXCEPTION 'Table % is not faceted', p_table; 219 | END IF; 220 | 221 | WITH dropped_facets AS ( 222 | DELETE FROM faceting.facet_definition 223 | WHERE table_id = v_table_id AND facet_name = ANY (facets) 224 | RETURNING facet_id, facet_name) 225 | SELECT array_agg(facet_id), array_agg(facet_name) INTO v_dropped_ids, v_dropped_names FROM dropped_facets; 226 | 227 | EXECUTE format('DELETE FROM %s WHERE facet_id = ANY ($1)', 228 | faceting._qualified(tdef.schemaname, tdef.facets_table)) 229 | USING v_dropped_ids; 230 | IF tdef.delta_table IS NOT NULL THEN 231 | -- Important to replace trigger first so deletion runs with a new snapshot 232 | PERFORM faceting.create_delta_trigger(v_table_id); 233 | EXECUTE format('DELETE FROM %s WHERE facet_id = ANY ($1)', 234 | faceting._qualified(tdef.schemaname, tdef.delta_table)) 235 | USING v_dropped_ids; 236 | END IF; 237 | 238 | RETURN QUERY SELECT unnest(v_dropped_names); 239 | END; 240 | $$; 241 | 242 | CREATE FUNCTION faceting.drop_faceting(p_table regclass) 243 | RETURNS bool 244 | LANGUAGE plpgsql 245 | AS $$ 246 | DECLARE 247 | v_table_id oid; 248 | tdef faceting.faceted_table; 249 | tfunc_name text; 250 | trg_name text; 251 | BEGIN 252 | v_table_id := p_table::oid; 253 | SELECT t.* INTO tdef FROM faceting.faceted_table t WHERE t.table_id = v_table_id; 254 | IF NOT FOUND THEN 255 | RAISE NOTICE 'Table % is not faceted', p_table; 256 | RETURN true; 257 | END IF; 258 | 259 | EXECUTE format('LOCK TABLE %s', faceting._qualified(tdef.schemaname, tdef.tablename)); 260 | 261 | DELETE FROM faceting.facet_definition WHERE table_id = v_table_id; 262 | DELETE FROM faceting.faceted_table WHERE table_id = v_table_id; 263 | 264 | EXECUTE format('DROP TABLE %s', faceting._qualified(tdef.schemaname, tdef.facets_table)); 265 | IF tdef.delta_table IS NOT NULL THEN 266 | SELECT tn.tfunc_name, tn.trg_name INTO tfunc_name, trg_name FROM faceting._trigger_names(tdef.tablename) tn; 267 | EXECUTE format('DROP TRIGGER %s ON %s', trg_name, faceting._qualified(tdef.schemaname, tdef.tablename)); 268 | EXECUTE format('DROP FUNCTION %s', faceting._qualified(tdef.schemaname, tfunc_name)); 269 | EXECUTE format('DROP TABLE %s', faceting._qualified(tdef.schemaname, tdef.delta_table)); 270 | END IF; 271 | 272 | RETURN true; 273 | END 274 | $$; 275 | CREATE FUNCTION faceting.populate_facets_query(p_table_id oid, facets text[] = null) 276 | RETURNS text 277 | LANGUAGE plpgsql 278 | AS $$ 279 | DECLARE 280 | sql text; 281 | values_entries text[]; 282 | subquery_entries text[]; 283 | clauses text[]; 284 | v_chunk_bits int; 285 | v_keycol name; 286 | tdef faceting.faceted_table; 287 | BEGIN 288 | SELECT t.* INTO tdef FROM faceting.faceted_table t WHERE t.table_id = p_table_id; 289 | SELECT chunk_bits, key INTO v_chunk_bits, v_keycol FROM faceting.faceted_table WHERE table_id = p_table_id; 290 | SELECT array_agg(faceting._get_values_clause(fd, '', 'd.') ORDER BY facet_id) INTO values_entries 291 | FROM faceting.facet_definition fd WHERE (facets IS NULL OR fd.facet_name = ANY (facets)) 292 | AND table_id = p_table_id AND NOT fd.is_multi; 293 | 294 | SELECT array_agg(faceting._get_subquery_clause(fd, '', 'd.')) INTO subquery_entries 295 | FROM faceting.facet_definition fd WHERE (facets IS NULL OR fd.facet_name = ANY (facets)) 296 | AND table_id = p_table_id AND fd.is_multi; 297 | 298 | IF array_length(values_entries, 1) > 0 THEN 299 | clauses := array[format('VALUES %s', array_to_string(values_entries, E',\n '))]; 300 | ELSE 301 | clauses := array[]; 302 | END IF; 303 | clauses := clauses || subquery_entries; 304 | 305 | sql := format($sql$ 306 | SELECT facet_id, (%s >> %s)::int4 chunk_id, facet_value collate "POSIX", rb_build_agg((%s & ((1 << %s) - 1))::int4 ORDER BY %s) 307 | FROM %s d, 308 | LATERAL ( 309 | %s 310 | ) t(facet_id, facet_value) 311 | WHERE facet_value IS NOT NULL 312 | GROUP BY facet_id, facet_value collate "POSIX", chunk_id 313 | $sql$, 314 | v_keycol, 315 | v_chunk_bits, 316 | v_keycol, 317 | v_chunk_bits, 318 | v_keycol, 319 | p_table_id::regclass::text, 320 | array_to_string(clauses, E'\n UNION ALL\n ') 321 | ); 322 | RETURN sql; 323 | END; 324 | $$; 325 | 326 | CREATE FUNCTION _trigger_names(tablename text, OUT tfunc_name text, OUT trg_name text) 327 | LANGUAGE plpgsql 328 | AS $$ 329 | BEGIN 330 | tfunc_name := faceting._identifier_append(tablename, '_facets_trigger'); 331 | trg_name := faceting._identifier_append(tablename, '_facets_update'); 332 | RETURN; 333 | END; 334 | $$; 335 | 336 | CREATE FUNCTION create_delta_trigger(p_table_id oid, p_create bool = true) 337 | RETURNS text 338 | LANGUAGE plpgsql 339 | AS $$ 340 | DECLARE 341 | tfunc_name text; 342 | trg_name text; 343 | sql text; 344 | tdef faceting.faceted_table; 345 | insert_values text[]; 346 | insert_subqueries text[]; 347 | insert_clauses text[]; 348 | delete_values text[]; 349 | delete_subqueries text[]; 350 | delete_clauses text[]; 351 | base_columns text[]; 352 | BEGIN 353 | SELECT t.* INTO tdef FROM faceting.faceted_table t WHERE t.table_id = p_table_id; 354 | SELECT tn.tfunc_name, tn.trg_name INTO tfunc_name, trg_name FROM faceting._trigger_names(tdef.tablename) tn; 355 | 356 | SELECT array_agg(faceting._get_values_clause(fd, format(', NEW.%I, 1', tdef.key) , 'NEW.') 357 | ORDER BY facet_id), 358 | array_agg(faceting._get_values_clause(fd, format(', OLD.%I, -1', tdef.key) , 'OLD.') 359 | ORDER BY facet_id), 360 | array_agg(fd.base_column) 361 | INTO insert_values, delete_values, base_columns 362 | FROM faceting.facet_definition fd WHERE table_id = p_table_id AND NOT fd.is_multi AND fd.supports_delta; 363 | 364 | SELECT array_agg(faceting._get_subquery_clause(fd, format(', NEW.%I, 1', tdef.key) , 'NEW.') 365 | ORDER BY facet_id), 366 | array_agg(faceting._get_subquery_clause(fd, format(', OLD.%I, -1', tdef.key) , 'OLD.') 367 | ORDER BY facet_id), 368 | array_agg(fd.base_column) || base_columns 369 | INTO insert_subqueries, delete_subqueries, base_columns 370 | FROM faceting.facet_definition fd WHERE table_id = p_table_id AND fd.is_multi AND fd.supports_delta; 371 | 372 | insert_clauses := CASE WHEN array_length(insert_values, 1) > 0 THEN 373 | array['VALUES ' || array_to_string(insert_values, E',\n ')] 374 | ELSE 375 | '{}'::text[] 376 | END || insert_subqueries; 377 | delete_clauses := CASE WHEN array_length(delete_values, 1) > 0 THEN 378 | array['VALUES ' || array_to_string(delete_values, E',\n ')] 379 | ELSE 380 | '{}'::text[] 381 | END || delete_subqueries; 382 | 383 | sql := format($sql$ 384 | CREATE OR REPLACE FUNCTION %s() RETURNS trigger AS $func$ 385 | BEGIN 386 | IF TG_OP = 'UPDATE' AND OLD.%I != NEW.%I THEN 387 | RAISE EXCEPTION 'Update of key column of faceted tables is not supported'; 388 | END IF; 389 | IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN 390 | INSERT INTO %s (facet_id, facet_value, posting, delta) 391 | SELECT * 392 | FROM ( 393 | %s 394 | ) AS deltas(facet_id, facet_value, posting, delta) 395 | WHERE facet_value IS NOT NULL 396 | ON CONFLICT (facet_id, facet_value, posting) DO UPDATE 397 | SET delta = EXCLUDED.delta + %s.delta; 398 | END IF; 399 | IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN 400 | INSERT INTO %s (facet_id, facet_value, posting, delta) 401 | SELECT * 402 | FROM ( 403 | %s 404 | ) AS deltas(facet_id, facet_value, posting, delta) 405 | WHERE facet_value IS NOT NULL 406 | ON CONFLICT (facet_id, facet_value, posting) DO UPDATE 407 | SET delta = EXCLUDED.delta + %s.delta; 408 | END IF; 409 | RETURN NULL; 410 | END; 411 | $func$ LANGUAGE plpgsql; 412 | 413 | CREATE OR REPLACE TRIGGER %s 414 | AFTER INSERT OR DELETE OR UPDATE OF %s ON %s 415 | FOR EACH ROW EXECUTE FUNCTION %s(); 416 | $sql$, 417 | -- Trigger name 418 | faceting._qualified(tdef.schemaname, tfunc_name), 419 | -- Key update check 420 | tdef.key, tdef.key, 421 | -- Positive deltas 422 | faceting._qualified(tdef.schemaname, tdef.delta_table), 423 | array_to_string(insert_clauses, E'\n UNION ALL\n '), 424 | faceting._qualified(tdef.schemaname, tdef.delta_table), 425 | -- Negative deltas 426 | faceting._qualified(tdef.schemaname, tdef.delta_table), 427 | array_to_string(delete_clauses, E'\n UNION ALL\n '), 428 | faceting._qualified(tdef.schemaname, tdef.delta_table), 429 | -- Trigger definition 430 | trg_name, 431 | array_to_string(base_columns, ', '), 432 | faceting._qualified(tdef.schemaname, tdef.tablename), 433 | faceting._qualified(tdef.schemaname, tfunc_name) 434 | ); 435 | IF p_create THEN 436 | EXECUTE sql; 437 | END IF; 438 | RETURN sql; 439 | END; 440 | $$; 441 | 442 | CREATE FUNCTION faceting.populate_facets(p_table_id oid, p_use_copy bool = false, debug bool = false, facets text[] = null) 443 | RETURNS void 444 | LANGUAGE plpgsql 445 | AS $$ 446 | DECLARE 447 | tdef faceting.faceted_table; 448 | query text; 449 | sql text; 450 | BEGIN 451 | SELECT t.* INTO tdef FROM faceting.faceted_table t WHERE t.table_id = p_table_id; 452 | IF tdef.table_id IS NULL THEN 453 | RAISE EXCEPTION 'Table % not found', p_table_id; 454 | END IF; 455 | query := faceting.populate_facets_query(p_table_id, facets => facets); 456 | IF p_use_copy THEN 457 | EXECUTE format($copy$COPY %s FROM PROGRAM $prog$ psql -h localhost %s -c "COPY (%s) TO STDOUT" $prog$ $copy$, 458 | faceting._qualified(tdef.schemaname, tdef.facets_table), 459 | current_database(), 460 | replace(query, '"', '\"')); 461 | RETURN; 462 | END IF; 463 | sql := format('INSERT INTO %s %s', faceting._qualified(tdef.schemaname, tdef.facets_table), query); 464 | IF debug THEN 465 | RAISE NOTICE '%s', sql; 466 | END IF; 467 | EXECUTE sql; 468 | END; 469 | $$; 470 | 471 | CREATE FUNCTION faceting.datetrunc_facet(col name, "precision" text, p_facet_name text = null) 472 | RETURNS facet_definition 473 | LANGUAGE SQL AS $$ 474 | SELECT null::int, null::int, coalesce(p_facet_name, col), 'datetrunc', col, jsonb_build_object('precision', "precision"), false, true; 475 | $$; 476 | 477 | CREATE FUNCTION faceting.datetrunc_facet_values(fdef facet_definition, extra_cols text, table_alias text) 478 | RETURNS text 479 | LANGUAGE plpgsql AS $$ 480 | BEGIN 481 | RETURN format('(%s, date_trunc(%L, %s%I)::text%s)', 482 | fdef.facet_id, fdef.params->>'precision', table_alias, fdef.base_column, extra_cols); 483 | END; 484 | $$; 485 | 486 | CREATE FUNCTION faceting.plain_facet(col name, p_facet_name text = null) 487 | RETURNS facet_definition 488 | LANGUAGE SQL AS $$ 489 | SELECT null::int, null::int, coalesce(p_facet_name, col), 'plain', col, '{}'::jsonb, false, true; 490 | $$; 491 | 492 | CREATE FUNCTION faceting.plain_facet_values(fdef facet_definition, extra_cols text, table_alias text) 493 | RETURNS text 494 | LANGUAGE plpgsql AS $$ 495 | BEGIN 496 | RETURN format('(%s, %s%I::text%s)', fdef.facet_id, table_alias, fdef.base_column, extra_cols); 497 | END; 498 | $$; 499 | 500 | CREATE FUNCTION faceting.bucket_facet(col name, buckets anyarray, p_facet_name text = null) 501 | RETURNS facet_definition 502 | LANGUAGE SQL AS $$ 503 | SELECT null::int, null::int, coalesce(p_facet_name, col), 'bucket', col, jsonb_build_object('buckets', buckets::text), false, true; 504 | $$; 505 | 506 | CREATE FUNCTION faceting.bucket_facet_values(fdef facet_definition, extra_cols text, table_alias text) 507 | RETURNS text 508 | LANGUAGE plpgsql AS $$ 509 | BEGIN 510 | RETURN format('(%s, width_bucket(%s%I, %L)::text%s)', 511 | fdef.facet_id, table_alias, fdef.base_column, fdef.params->>'buckets', extra_cols); 512 | END; 513 | $$; 514 | 515 | CREATE FUNCTION faceting.array_facet(col name, p_facet_name text = null) 516 | RETURNS facet_definition 517 | LANGUAGE SQL AS $$ 518 | SELECT null::int, null::int, coalesce(p_facet_name, col), 'array', col, '{}'::jsonb, true, true; 519 | $$; 520 | 521 | CREATE FUNCTION faceting.array_facet_subquery(fdef facet_definition, extra_cols text, table_alias text) 522 | RETURNS text 523 | LANGUAGE plpgsql AS $$ 524 | BEGIN 525 | RETURN format('(SELECT %s, element_value::text%s FROM unnest(%s%I) element_value)', 526 | fdef.facet_id, extra_cols, table_alias, fdef.base_column); 527 | END; 528 | $$; 529 | 530 | CREATE FUNCTION faceting.joined_plain_facet(col text, from_clause text, correlation text, p_facet_name text = null) 531 | RETURNS facet_definition 532 | LANGUAGE plpgsql AS $$ 533 | DECLARE 534 | base_col_name text; 535 | BEGIN 536 | SELECT ident[array_upper(ident, 1)] INTO base_col_name FROM parse_ident(col) ident; 537 | RETURN row(null::oid, null::int, coalesce(p_facet_name, base_col_name), 'joined_plain'::text, NULL::name, 538 | jsonb_build_object('col', col, 'from_clause', from_clause, 'correlation', correlation), 539 | true, false); 540 | END; 541 | $$; 542 | 543 | CREATE FUNCTION faceting.joined_plain_facet_subquery(fdef facet_definition, extra_cols text, table_alias text) 544 | RETURNS text 545 | LANGUAGE plpgsql AS $$ 546 | DECLARE 547 | correlation_clause text; 548 | BEGIN 549 | correlation_clause := replace(fdef.params->>'correlation', '{TABLE}.', table_alias); 550 | RETURN format('(SELECT %s, %s::text%s FROM %s WHERE %s)', 551 | fdef.facet_id, fdef.params->>'col', extra_cols, fdef.params->>'from_clause', correlation_clause); 552 | END; 553 | $$; 554 | 555 | CREATE TYPE faceting.facet_counts AS ( 556 | facet_name text, 557 | facet_value text, 558 | cardinality int8 559 | ); 560 | 561 | CREATE FUNCTION faceting.top_values(p_table_id oid, n int = 5, facets text[] = null) 562 | RETURNS SETOF faceting.facet_counts 563 | LANGUAGE plpgsql 564 | AS $$ 565 | DECLARE 566 | tdef faceting.faceted_table; 567 | facet_filter text = ''; 568 | BEGIN 569 | SELECT t.* INTO tdef FROM faceting.faceted_table t WHERE t.table_id = p_table_id; 570 | IF tdef.table_id IS NULL THEN 571 | RAISE EXCEPTION 'Table % not found', p_table_id; 572 | END IF; 573 | IF facets IS NOT NULL THEN 574 | SELECT format('WHERE facet_id = ANY (''%s'')', array_agg(facet_id)::text) INTO facet_filter 575 | FROM faceting.facet_definition fd WHERE fd.facet_name = ANY (facets); 576 | END IF; 577 | 578 | RETURN QUERY EXECUTE format($sql$ 579 | SELECT facet_name, facet_value, sum::int8 FROM ( 580 | SELECT facet_id, facet_value, sum, rank() OVER (PARTITION BY facet_id ORDER BY sum DESC) rank 581 | FROM ( 582 | SELECT facet_id, facet_value, sum(rb_cardinality(postinglist)) 583 | FROM %s 584 | %s 585 | GROUP BY 1, 2 586 | ) x 587 | ) counts JOIN faceting.facet_definition fd USING (facet_id) 588 | WHERE rank <= 5 AND table_id = $1 589 | ORDER BY facet_id, rank, facet_value; 590 | $sql$, 591 | faceting._qualified(tdef.schemaname, tdef.facets_table), 592 | facet_filter) 593 | USING p_table_id; 594 | END; 595 | $$; 596 | 597 | CREATE TYPE faceting.facet_filter AS 598 | ( 599 | facet_name text, 600 | facet_value text 601 | ); 602 | 603 | CREATE FUNCTION faceting.count_results(p_table_id oid, filters facet_filter[]) 604 | RETURNS SETOF faceting.facet_counts 605 | LANGUAGE plpgsql 606 | AS $$ 607 | DECLARE 608 | tdef faceting.faceted_table; 609 | select_facets int[]; 610 | sql text; 611 | BEGIN 612 | SELECT t.* INTO tdef FROM faceting.faceted_table t WHERE t.table_id = p_table_id; 613 | IF tdef.table_id IS NULL THEN 614 | RAISE EXCEPTION 'Table % not found', p_table_id; 615 | END IF; 616 | 617 | SELECT array_agg(facet_id) INTO select_facets 618 | FROM faceting.facet_definition 619 | WHERE table_id = p_table_id 620 | AND facet_name NOT IN (SELECT f.facet_name FROM unnest(filters) f); 621 | 622 | sql := format($sql$ 623 | WITH filters AS ( 624 | SELECT facet_id, facet_name, facet_value 625 | FROM faceting.facet_definition JOIN unnest($1) t USING (facet_name) 626 | WHERE table_id = $2 627 | ), lookup AS ( 628 | SELECT chunk_id, rb_and_agg(postinglist) postinglist 629 | FROM %s d JOIN filters USING (facet_id, facet_value) 630 | GROUP BY chunk_id 631 | ), results AS ( 632 | SELECT facet_id, facet_value, sum(rb_and_cardinality(lookup.postinglist, d.postinglist))::int8 cardinality 633 | FROM lookup JOIN %s d USING (chunk_id) 634 | WHERE facet_id = ANY ($3) 635 | GROUP BY facet_id, facet_value 636 | ) 637 | SELECT facet_name, facet_value, cardinality 638 | FROM results JOIN faceting.facet_definition fd USING (facet_id) 639 | WHERE fd.table_id = $2 640 | ORDER BY facet_id, cardinality DESC, facet_value 641 | $sql$, 642 | faceting._qualified(tdef.schemaname, tdef.facets_table), 643 | faceting._qualified(tdef.schemaname, tdef.facets_table)); 644 | 645 | RETURN QUERY EXECUTE sql USING filters, p_table_id, select_facets; 646 | END; 647 | $$; 648 | 649 | CREATE FUNCTION faceting.merge_deltas(p_table_id oid) 650 | RETURNS void 651 | LANGUAGE plpgsql AS $$ 652 | DECLARE 653 | sql text; 654 | tdef faceting.faceted_table; 655 | BEGIN 656 | SELECT t.* INTO tdef FROM faceting.faceted_table t WHERE t.table_id = p_table_id; 657 | IF tdef.table_id IS NULL THEN 658 | RAISE EXCEPTION 'Table % not found', p_table_id; 659 | END IF; 660 | 661 | sql := format($sql$ 662 | WITH to_be_aggregated AS (DELETE FROM %s RETURNING *), 663 | chunk_deltas AS ( 664 | SELECT facet_id, 665 | (posting >> %s) chunk_id, 666 | facet_value, 667 | coalesce(rb_build_agg((posting & ((1<<%s) - 1))::int4) FILTER (WHERE delta > 0), '\x3a30000000000000') AS postings_added, 668 | coalesce(rb_build_agg((posting & ((1<<%s) - 1))::int4) FILTER (WHERE delta < 0), '\x3a30000000000000') AS postings_deleted 669 | FROM to_be_aggregated 670 | GROUP BY 1,2,3 671 | ), 672 | updates AS (UPDATE %s AS d 673 | SET postinglist = rb_or(rb_andnot(postinglist, postings_deleted), postings_added) 674 | FROM chunk_deltas 675 | WHERE d.facet_id = chunk_deltas.facet_id 676 | AND d.facet_value = chunk_deltas.facet_value 677 | AND d.chunk_id = chunk_deltas.chunk_id) 678 | INSERT INTO %s SELECT facet_id, chunk_id, facet_value, postings_added 679 | FROM chunk_deltas 680 | ON CONFLICT (facet_id, facet_value, chunk_id) DO NOTHING; 681 | $sql$, 682 | faceting._qualified(tdef.schemaname, tdef.delta_table), 683 | tdef.chunk_bits, tdef.chunk_bits, tdef.chunk_bits, 684 | faceting._qualified(tdef.schemaname, tdef.facets_table), 685 | faceting._qualified(tdef.schemaname, tdef.facets_table) 686 | ); 687 | EXECUTE sql; 688 | RETURN; 689 | END; 690 | $$; 691 | 692 | CREATE PROCEDURE faceting.run_maintenance(debug bool = false) 693 | LANGUAGE plpgsql 694 | AS $$ 695 | DECLARE 696 | tdef faceting.faceted_table; 697 | start_ts timestamptz; 698 | end_ts timestamptz; 699 | BEGIN 700 | FOR tdef IN SELECT * FROM faceting.faceted_table LOOP 701 | IF debug THEN 702 | RAISE NOTICE 'Starting facets maintenance of %', tdef.tablename; 703 | END IF; 704 | start_ts := clock_timestamp(); 705 | PERFORM faceting.merge_deltas(tdef.table_id); 706 | COMMIT; 707 | end_ts := clock_timestamp(); 708 | IF debug THEN 709 | RAISE NOTICE 'End facets maintenance of %, duration: %s', tdef.tablename, end_ts - start_ts; 710 | END IF; 711 | END LOOP; 712 | END; 713 | $$; 714 | 715 | -------------------------------------------------------------------------------- /test/expected/base.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION roaringbitmap; 2 | CREATE EXTENSION pgfaceting; 3 | CREATE SCHEMA facetingtestsuite; 4 | CREATE TYPE facetingtestsuite.mimetype AS ENUM ( 5 | 'application/pdf', 6 | 'text/html', 7 | 'image/jpeg', 8 | 'image/png', 9 | 'application/msword', 10 | 'text/csv', 11 | 'application/zip', 12 | 'application/vnd.ms-powerpoint' 13 | ); 14 | CREATE TABLE facetingtestsuite.employee ( 15 | id int8 primary key, 16 | full_name text, 17 | department text 18 | ); 19 | CREATE TABLE facetingtestsuite.categories ( 20 | id int8 primary key, 21 | owner_id int8 REFERENCES facetingtestsuite.employee (id) 22 | ); 23 | CREATE TABLE facetingtestsuite.documents ( 24 | id int8 primary key, 25 | created timestamptz not null, 26 | finished timestamptz, 27 | category_id int8 REFERENCES facetingtestsuite.categories (id), 28 | tags text[], 29 | type facetingtestsuite.mimetype, 30 | size int8, 31 | title text 32 | ); 33 | CREATE TABLE facetingtestsuite.authors ( 34 | document_id int8 REFERENCES facetingtestsuite.documents (id) ON DELETE CASCADE, 35 | author_id int8 REFERENCES facetingtestsuite.employee (id), 36 | PRIMARY KEY (document_id, author_id) 37 | ); 38 | COPY facetingtestsuite.employee (id, full_name, department) FROM stdin; 39 | COPY facetingtestsuite.categories (id, owner_id) FROM stdin; 40 | COPY facetingtestsuite.documents (id, created, finished, category_id, tags, type, size, title) FROM stdin; 41 | COPY facetingtestsuite.authors FROM stdin; 42 | SELECT faceting.add_faceting_to_table('facetingtestsuite.documents', 43 | key => 'id', 44 | facets => array[ 45 | faceting.datetrunc_facet('created', 'month'), 46 | faceting.datetrunc_facet('finished', 'month'), 47 | faceting.plain_facet('category_id'), 48 | faceting.array_facet('tags'), 49 | faceting.bucket_facet('size', buckets => array[0,1000,5000,10000,50000,100000,500000]), 50 | faceting.joined_plain_facet('author_id', 51 | from_clause => 'facetingtestsuite.authors a', 52 | correlation => 'a.document_id = {TABLE}.id', 53 | p_facet_name => 'author') 54 | ], 55 | populate => false 56 | ); 57 | add_faceting_to_table 58 | ----------------------- 59 | 60 | (1 row) 61 | 62 | SELECT faceting.populate_facets('facetingtestsuite.documents'::regclass); 63 | populate_facets 64 | ----------------- 65 | 66 | (1 row) 67 | 68 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 69 | facet_name | facet_value | cardinality 70 | -------------+------------------------------+------------- 71 | created | Tue Dec 01 00:00:00 2009 PST | 10 72 | finished | Fri Jan 01 00:00:00 2010 PST | 6 73 | finished | Tue Dec 01 00:00:00 2009 PST | 4 74 | category_id | 24 | 4 75 | category_id | 8 | 2 76 | category_id | 9 | 2 77 | category_id | 12 | 1 78 | tags | blue | 7 79 | tags | orange | 5 80 | tags | green | 4 81 | tags | burlywood | 2 82 | tags | olive | 2 83 | size | 6 | 7 84 | size | 7 | 2 85 | size | 5 | 1 86 | author | 1 | 7 87 | author | 2 | 4 88 | author | 3 | 2 89 | (18 rows) 90 | 91 | SELECT faceting.add_facets('facetingtestsuite.documents', 92 | facets=>array[ 93 | faceting.plain_facet('type'), 94 | faceting.joined_plain_facet('e.department', 95 | from_clause => 'facetingtestsuite.categories c JOIN facetingtestsuite.employee e ON c.owner_id = e.id', 96 | correlation => 'c.id = {TABLE}.category_id') 97 | ]); 98 | add_facets 99 | ------------ 100 | 7 101 | 8 102 | (2 rows) 103 | 104 | SELECT faceting.populate_facets_query('facetingtestsuite.documents'::regclass::oid); 105 | populate_facets_query 106 | -------------------------------------------------------------------------------------------------------------------------------------------------------------- 107 | + 108 | SELECT facet_id, (id >> 20)::int4 chunk_id, facet_value collate "POSIX", rb_build_agg((id & ((1 << 20) - 1))::int4 ORDER BY id) + 109 | FROM facetingtestsuite.documents d, + 110 | LATERAL ( + 111 | VALUES (1, date_trunc('month', d.created)::text), + 112 | (2, date_trunc('month', d.finished)::text), + 113 | (3, d.category_id::text), + 114 | (5, width_bucket(d.size, '{0,1000,5000,10000,50000,100000,500000}')::text), + 115 | (7, d.type::text) + 116 | UNION ALL + 117 | (SELECT 4, element_value::text FROM unnest(d.tags) element_value) + 118 | UNION ALL + 119 | (SELECT 6, author_id::text FROM facetingtestsuite.authors a WHERE a.document_id = d.id) + 120 | UNION ALL + 121 | (SELECT 8, e.department::text FROM facetingtestsuite.categories c JOIN facetingtestsuite.employee e ON c.owner_id = e.id WHERE c.id = d.category_id)+ 122 | ) t(facet_id, facet_value) + 123 | WHERE facet_value IS NOT NULL + 124 | GROUP BY facet_id, facet_value collate "POSIX", chunk_id + 125 | 126 | (1 row) 127 | 128 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 129 | facet_name | facet_value | cardinality 130 | -------------+------------------------------+------------- 131 | created | Tue Dec 01 00:00:00 2009 PST | 10 132 | finished | Fri Jan 01 00:00:00 2010 PST | 6 133 | finished | Tue Dec 01 00:00:00 2009 PST | 4 134 | category_id | 24 | 4 135 | category_id | 8 | 2 136 | category_id | 9 | 2 137 | category_id | 12 | 1 138 | tags | blue | 7 139 | tags | orange | 5 140 | tags | green | 4 141 | tags | burlywood | 2 142 | tags | olive | 2 143 | size | 6 | 7 144 | size | 7 | 2 145 | size | 5 | 1 146 | author | 1 | 7 147 | author | 2 | 4 148 | author | 3 | 2 149 | type | application/pdf | 5 150 | type | text/html | 3 151 | type | image/jpeg | 2 152 | department | Sales | 7 153 | department | Director | 2 154 | (23 rows) 155 | 156 | COPY facetingtestsuite.documents (id, created, finished, category_id, tags, type, size, title) FROM stdin; 157 | SELECT faceting.merge_deltas('facetingtestsuite.documents'::regclass); 158 | merge_deltas 159 | -------------- 160 | 161 | (1 row) 162 | 163 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 164 | facet_name | facet_value | cardinality 165 | -------------+------------------------------+------------- 166 | created | Tue Dec 01 00:00:00 2009 PST | 20 167 | finished | Fri Jan 01 00:00:00 2010 PST | 15 168 | finished | Tue Dec 01 00:00:00 2009 PST | 5 169 | category_id | 24 | 12 170 | category_id | 9 | 4 171 | category_id | 8 | 2 172 | category_id | 12 | 1 173 | tags | blue | 15 174 | tags | orange | 14 175 | tags | green | 6 176 | tags | brown | 4 177 | tags | red | 3 178 | size | 6 | 14 179 | size | 7 | 4 180 | size | 4 | 1 181 | size | 5 | 1 182 | author | 1 | 7 183 | author | 2 | 4 184 | author | 3 | 2 185 | type | application/pdf | 10 186 | type | image/jpeg | 3 187 | type | image/png | 3 188 | type | text/html | 3 189 | type | text/csv | 1 190 | department | Sales | 7 191 | department | Director | 2 192 | (26 rows) 193 | 194 | (SELECT 'created' AS facet_name, date_trunc('month', created)::text AS facet_value, COUNT(*) AS cardinality FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5) 195 | UNION ALL 196 | (SELECT 'finished', date_trunc('month', finished)::text, COUNT(*) FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5) 197 | UNION ALL 198 | (SELECT 'category_id', category_id::text, COUNT(*) FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5) 199 | UNION ALL 200 | (SELECT 'type', type::text, COUNT(*) FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5) 201 | UNION ALL 202 | (SELECT 'size', width_bucket(size, array[0,1000,5000,10000,50000,100000,500000])::text, COUNT(*) FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5); 203 | facet_name | facet_value | cardinality 204 | -------------+------------------------------+------------- 205 | created | Tue Dec 01 00:00:00 2009 PST | 20 206 | finished | Fri Jan 01 00:00:00 2010 PST | 15 207 | finished | Tue Dec 01 00:00:00 2009 PST | 5 208 | category_id | 24 | 12 209 | category_id | 9 | 4 210 | category_id | 8 | 2 211 | category_id | 12 | 1 212 | category_id | | 1 213 | type | application/pdf | 10 214 | type | image/jpeg | 3 215 | type | image/png | 3 216 | type | text/html | 3 217 | type | text/csv | 1 218 | size | 6 | 14 219 | size | 7 | 4 220 | size | 4 | 1 221 | size | 5 | 1 222 | (17 rows) 223 | 224 | SELECT * FROM faceting.count_results('facetingtestsuite.documents'::regclass, 225 | filters => array[row('category_id', 24)]::faceting.facet_filter[]); 226 | facet_name | facet_value | cardinality 227 | ------------+------------------------------+------------- 228 | created | Tue Dec 01 00:00:00 2009 PST | 12 229 | finished | Fri Jan 01 00:00:00 2010 PST | 10 230 | finished | Tue Dec 01 00:00:00 2009 PST | 2 231 | tags | orange | 11 232 | tags | blue | 9 233 | tags | green | 5 234 | tags | brown | 4 235 | tags | red | 3 236 | tags | darkslateblue | 2 237 | tags | aqua | 1 238 | tags | burlywood | 1 239 | tags | cadetblue | 1 240 | tags | candy pink | 1 241 | tags | chartreuse | 1 242 | tags | cherry | 1 243 | tags | chocolate | 1 244 | tags | coral | 1 245 | tags | cyan | 1 246 | tags | dimgray | 1 247 | tags | dirt brown | 1 248 | tags | floralwhite | 1 249 | tags | ivory | 1 250 | tags | lavender | 1 251 | tags | lightpink | 1 252 | tags | maroon | 1 253 | tags | olive | 1 254 | tags | pale gold | 1 255 | tags | pale peach | 1 256 | tags | peachy pink | 1 257 | tags | purple | 1 258 | tags | antiquewhite | 0 259 | tags | aqua blue | 0 260 | tags | aquamarine | 0 261 | tags | bisque | 0 262 | tags | lightcoral | 0 263 | tags | mustard brown | 0 264 | tags | pink | 0 265 | tags | red purple | 0 266 | tags | rust | 0 267 | tags | very light pink | 0 268 | size | 6 | 9 269 | size | 7 | 2 270 | size | 4 | 1 271 | size | 5 | 0 272 | author | 1 | 3 273 | author | 2 | 2 274 | author | 3 | 1 275 | type | application/pdf | 5 276 | type | image/jpeg | 3 277 | type | text/html | 2 278 | type | image/png | 1 279 | type | text/csv | 1 280 | department | Sales | 4 281 | department | Director | 0 282 | (54 rows) 283 | 284 | DELETE FROM facetingtestsuite.documents WHERE 'red' = ANY (tags); 285 | SELECT faceting.merge_deltas('facetingtestsuite.documents'::regclass); 286 | merge_deltas 287 | -------------- 288 | 289 | (1 row) 290 | 291 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass, facets=>array['tags', 'type']); 292 | facet_name | facet_value | cardinality 293 | ------------+-----------------+------------- 294 | tags | blue | 13 295 | tags | orange | 11 296 | tags | green | 5 297 | tags | brown | 4 298 | tags | aqua | 2 299 | tags | burlywood | 2 300 | tags | olive | 2 301 | type | application/pdf | 9 302 | type | image/png | 3 303 | type | image/jpeg | 2 304 | type | text/html | 2 305 | type | text/csv | 1 306 | (12 rows) 307 | 308 | SELECT faceting.drop_facets('facetingtestsuite.documents', array['type', 'tags', 'not existing']); 309 | drop_facets 310 | ------------- 311 | tags 312 | type 313 | (2 rows) 314 | 315 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 316 | facet_name | facet_value | cardinality 317 | -------------+------------------------------+------------- 318 | created | Tue Dec 01 00:00:00 2009 PST | 17 319 | finished | Fri Jan 01 00:00:00 2010 PST | 13 320 | finished | Tue Dec 01 00:00:00 2009 PST | 4 321 | category_id | 24 | 9 322 | category_id | 9 | 4 323 | category_id | 8 | 2 324 | category_id | 12 | 1 325 | size | 6 | 11 326 | size | 7 | 4 327 | size | 4 | 1 328 | size | 5 | 1 329 | author | 1 | 7 330 | author | 2 | 4 331 | author | 3 | 2 332 | department | Sales | 7 333 | department | Director | 2 334 | (16 rows) 335 | 336 | SELECT faceting.drop_faceting('facetingtestsuite.documents'); 337 | drop_faceting 338 | --------------- 339 | t 340 | (1 row) 341 | 342 | -- Check that adding faceting back in works 343 | SELECT faceting.add_faceting_to_table('facetingtestsuite.documents', 344 | key => 'id', 345 | facets => array[faceting.plain_facet('category_id')]); 346 | add_faceting_to_table 347 | ----------------------- 348 | 349 | (1 row) 350 | 351 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 352 | facet_name | facet_value | cardinality 353 | -------------+-------------+------------- 354 | category_id | 24 | 9 355 | category_id | 9 | 4 356 | category_id | 8 | 2 357 | category_id | 12 | 1 358 | (4 rows) 359 | 360 | -------------------------------------------------------------------------------- /test/expected/error_checks.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION IF NOT EXISTS roaringbitmap; 2 | NOTICE: extension "roaringbitmap" already exists, skipping 3 | CREATE EXTENSION IF NOT EXISTS pgfaceting; 4 | NOTICE: extension "pgfaceting" already exists, skipping 5 | CREATE SCHEMA errorchecks; 6 | SET SEARCH_PATH = 'errorchecks', 'public'; 7 | CREATE TABLE uuid_based_docs ( 8 | id uuid primary key, 9 | type text 10 | ); 11 | CREATE TABLE text_based_docs ( 12 | id text primary key, 13 | type text 14 | ); 15 | CREATE TABLE int4_based_docs ( 16 | id int4 primary key, 17 | type text 18 | ); 19 | -- Expected error on key col not existing 20 | SELECT faceting.add_faceting_to_table('uuid_based_docs', 21 | key => 'nonexistent', 22 | facets => array[faceting.plain_facet('type')] 23 | ); 24 | ERROR: Key column nonexistent not found in errorcheckss.uuid_based_docss 25 | CONTEXT: PL/pgSQL function faceting.add_faceting_to_table(regclass,name,faceting.facet_definition[],integer,boolean,boolean) line 30 at RAISE 26 | -- Expected error on wrong type key column 27 | SELECT faceting.add_faceting_to_table('uuid_based_docs', 28 | key => 'id', 29 | facets => array[faceting.plain_facet('type')] 30 | ); 31 | ERROR: Key column type uuid is not supported. 32 | CONTEXT: PL/pgSQL function faceting.add_faceting_to_table(regclass,name,faceting.facet_definition[],integer,boolean,boolean) line 32 at RAISE 33 | SELECT faceting.add_faceting_to_table('text_based_docs', 34 | key => 'id', 35 | facets => array[faceting.plain_facet('type')] 36 | ); 37 | ERROR: Key column type text is not supported. 38 | CONTEXT: PL/pgSQL function faceting.add_faceting_to_table(regclass,name,faceting.facet_definition[],integer,boolean,boolean) line 32 at RAISE 39 | -- Wrong chunk bits 40 | SELECT faceting.add_faceting_to_table('int4_based_docs', 41 | key => 'id', 42 | chunk_bits => 42, 43 | facets => array[faceting.plain_facet('type')] 44 | ); 45 | ERROR: Invalid number of bits per chunk: 42 46 | CONTEXT: PL/pgSQL function faceting.add_faceting_to_table(regclass,name,faceting.facet_definition[],integer,boolean,boolean) line 19 at RAISE 47 | -- Not faceted table 48 | SELECT faceting.add_facets('int4_based_docs', facets => array[faceting.plain_facet('type')]); 49 | ERROR: Table int4_based_docs is not faceted 50 | CONTEXT: PL/pgSQL function faceting.add_facets(regclass,faceting.facet_definition[],boolean) line 12 at RAISE 51 | -- Expected no error 52 | SELECT faceting.add_faceting_to_table('int4_based_docs', 53 | key => 'id', 54 | facets => array[faceting.plain_facet('type')] 55 | ); 56 | add_faceting_to_table 57 | ----------------------- 58 | 59 | (1 row) 60 | 61 | -------------------------------------------------------------------------------- /test/sql/base.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION roaringbitmap; 2 | CREATE EXTENSION pgfaceting; 3 | 4 | CREATE SCHEMA facetingtestsuite; 5 | 6 | CREATE TYPE facetingtestsuite.mimetype AS ENUM ( 7 | 'application/pdf', 8 | 'text/html', 9 | 'image/jpeg', 10 | 'image/png', 11 | 'application/msword', 12 | 'text/csv', 13 | 'application/zip', 14 | 'application/vnd.ms-powerpoint' 15 | ); 16 | 17 | CREATE TABLE facetingtestsuite.employee ( 18 | id int8 primary key, 19 | full_name text, 20 | department text 21 | ); 22 | 23 | CREATE TABLE facetingtestsuite.categories ( 24 | id int8 primary key, 25 | owner_id int8 REFERENCES facetingtestsuite.employee (id) 26 | ); 27 | 28 | CREATE TABLE facetingtestsuite.documents ( 29 | id int8 primary key, 30 | created timestamptz not null, 31 | finished timestamptz, 32 | category_id int8 REFERENCES facetingtestsuite.categories (id), 33 | tags text[], 34 | type facetingtestsuite.mimetype, 35 | size int8, 36 | title text 37 | ); 38 | 39 | CREATE TABLE facetingtestsuite.authors ( 40 | document_id int8 REFERENCES facetingtestsuite.documents (id) ON DELETE CASCADE, 41 | author_id int8 REFERENCES facetingtestsuite.employee (id), 42 | PRIMARY KEY (document_id, author_id) 43 | ); 44 | 45 | COPY facetingtestsuite.employee (id, full_name, department) FROM stdin; 46 | 1 John Smith Director 47 | 2 Jane Doe Sales 48 | 3 Jill James Sales 49 | \. 50 | 51 | COPY facetingtestsuite.categories (id, owner_id) FROM stdin; 52 | 8 2 53 | 9 1 54 | 12 3 55 | 24 2 56 | \. 57 | 58 | COPY facetingtestsuite.documents (id, created, finished, category_id, tags, type, size, title) FROM stdin; 59 | 1 2010-01-01 00:00:42+02 2010-01-01 09:45:29+02 8 {blue,burlywood,antiquewhite,olive} application/pdf 71205 Interracial marriage Science Research 60 | 2 2010-01-01 00:00:37+02 2010-01-01 03:55:08+02 12 {lightcoral,bisque,blue,"aqua blue","red purple",aqua} text/html 682069 Odour and trials helped to improve the country's history through the public 61 | 3 2010-01-01 00:00:33+02 2010-01-02 18:29:15+02 9 {"mustard brown","very light pink"} application/pdf 143708 Have technical scale, ordinary, commonsense notions of absolute time and length independent of the 62 | 4 2010-01-01 00:00:35+02 2010-01-02 01:12:08+02 24 {orange,green,blue} text/html 280663 Database of (/ˈdɛnmɑːrk/; Danish: Danmark [ˈd̥ænmɑɡ̊]) is a spiral 63 | 5 2010-01-01 00:01:06+02 2010-01-01 23:18:56+02 24 {orange,chocolate} image/jpeg 111770 Passage to now resumed 64 | 6 2010-01-01 00:01:05+02 2010-01-01 10:25:29+02 8 {blue,aquamarine} application/pdf 110809 East. Mesopotamia, BCE – 480 BCE), when determining a value that 65 | 7 2010-01-01 00:00:57+02 2010-01-02 00:41:01+02 \N {} application/pdf 230803 Bahía de It has also conquered 13 South American finds and another 66 | 8 2010-01-01 00:01:11+02 2010-01-01 14:22:11+02 24 {blue,burlywood,"dirt brown",orange,ivory,brown,green,olive,lightpink} image/jpeg 1304196 15-fold: from the mid- to late-20th 67 | 9 2010-01-01 00:01:47+02 2010-01-01 09:59:57+02 9 {green,blue,orange} application/pdf 142410 Popular Western localized function model. Psychiatric interventions such as local businesses, but also 68 | 10 2010-01-01 00:01:31+02 2010-01-01 05:49:47+02 24 {green,lavender,blue,orange,red,darkslateblue} text/html 199703 Rapidly expanding Large Interior Form, 1953-54, Man Enters the Cosmos and Nuclear Energy. 69 | \. 70 | 71 | COPY facetingtestsuite.authors FROM stdin; 72 | 1 1 73 | 1 2 74 | 2 1 75 | 3 1 76 | 4 1 77 | 4 2 78 | 4 3 79 | 5 1 80 | 5 2 81 | 6 2 82 | 7 3 83 | 9 1 84 | 10 1 85 | \. 86 | 87 | SELECT faceting.add_faceting_to_table('facetingtestsuite.documents', 88 | key => 'id', 89 | facets => array[ 90 | faceting.datetrunc_facet('created', 'month'), 91 | faceting.datetrunc_facet('finished', 'month'), 92 | faceting.plain_facet('category_id'), 93 | faceting.array_facet('tags'), 94 | faceting.bucket_facet('size', buckets => array[0,1000,5000,10000,50000,100000,500000]), 95 | faceting.joined_plain_facet('author_id', 96 | from_clause => 'facetingtestsuite.authors a', 97 | correlation => 'a.document_id = {TABLE}.id', 98 | p_facet_name => 'author') 99 | ], 100 | populate => false 101 | ); 102 | 103 | SELECT faceting.populate_facets('facetingtestsuite.documents'::regclass); 104 | 105 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 106 | 107 | SELECT faceting.add_facets('facetingtestsuite.documents', 108 | facets=>array[ 109 | faceting.plain_facet('type'), 110 | faceting.joined_plain_facet('e.department', 111 | from_clause => 'facetingtestsuite.categories c JOIN facetingtestsuite.employee e ON c.owner_id = e.id', 112 | correlation => 'c.id = {TABLE}.category_id') 113 | 114 | ]); 115 | 116 | SELECT faceting.populate_facets_query('facetingtestsuite.documents'::regclass::oid); 117 | 118 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 119 | 120 | COPY facetingtestsuite.documents (id, created, finished, category_id, tags, type, size, title) FROM stdin; 121 | 11 2010-01-01 00:01:21+02 2010-01-01 20:31:12+02 9 {blue,pink,orange} image/png 679323 Additional 32 Martin, Saint Pierre and 122 | 12 2010-01-01 00:02:12+02 2010-01-02 10:33:25+02 24 {green,maroon,blue,coral,orange} application/pdf 166940 To harness between continents. By the mid-19th century? 123 | 13 2010-01-01 00:02:20+02 2010-01-01 03:59:11+02 24 {orange,"pale peach",blue,"peachy pink",chartreuse,aqua,brown} application/pdf 333191 The synchrocyclotron, been exposed 124 | 14 2010-01-01 00:02:32+02 2010-01-01 18:50:37+02 24 {orange,cherry,brown} application/pdf 12421 And supernovae as ways to indirectly measure these elusive phenomenological entities. 125 | 15 2010-01-01 00:02:47+02 2010-01-01 14:29:27+02 24 {orange,blue,cyan,red,floralwhite,darkslateblue} application/pdf 459132 Ratio. \n the nucleus of a cumulus or cumulonimbus. 126 | 16 2010-01-01 00:02:38+02 2010-01-01 20:53:15+02 24 {blue,orange,purple,"pale gold"} application/pdf 140909 Pacific. A observance of halakha may pose serious 127 | 17 2010-01-01 00:02:48+02 2010-01-02 08:19:47+02 9 {orange,blue,rust} image/png 414066 Gravity equivalent, it attract the wrath of 128 | 18 2010-01-01 00:03:05+02 2010-01-02 15:16:47+02 24 {dimgray,orange,red} image/jpeg 113942 Jim Crow classification methods including 129 | 19 2010-01-01 00:03:23+02 2010-01-02 06:33:01+02 24 {"candy pink",blue,orange,brown} text/csv 100419 Trans-Atlantic trade archdioceses, the Archdiocese of Atlanta. 130 | 20 2010-01-01 00:03:23+02 2010-01-02 02:24:17+02 24 {cadetblue,blue,green} image/png 705939 Normandy with others. Laughter is a kind of case that 131 | \. 132 | 133 | SELECT faceting.merge_deltas('facetingtestsuite.documents'::regclass); 134 | 135 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 136 | 137 | (SELECT 'created' AS facet_name, date_trunc('month', created)::text AS facet_value, COUNT(*) AS cardinality FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5) 138 | UNION ALL 139 | (SELECT 'finished', date_trunc('month', finished)::text, COUNT(*) FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5) 140 | UNION ALL 141 | (SELECT 'category_id', category_id::text, COUNT(*) FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5) 142 | UNION ALL 143 | (SELECT 'type', type::text, COUNT(*) FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5) 144 | UNION ALL 145 | (SELECT 'size', width_bucket(size, array[0,1000,5000,10000,50000,100000,500000])::text, COUNT(*) FROM facetingtestsuite.documents GROUP BY 1, 2 ORDER BY 3 DESC, 2 LIMIT 5); 146 | 147 | SELECT * FROM faceting.count_results('facetingtestsuite.documents'::regclass, 148 | filters => array[row('category_id', 24)]::faceting.facet_filter[]); 149 | 150 | DELETE FROM facetingtestsuite.documents WHERE 'red' = ANY (tags); 151 | 152 | SELECT faceting.merge_deltas('facetingtestsuite.documents'::regclass); 153 | 154 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass, facets=>array['tags', 'type']); 155 | 156 | SELECT faceting.drop_facets('facetingtestsuite.documents', array['type', 'tags', 'not existing']); 157 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 158 | 159 | SELECT faceting.drop_faceting('facetingtestsuite.documents'); 160 | 161 | -- Check that adding faceting back in works 162 | SELECT faceting.add_faceting_to_table('facetingtestsuite.documents', 163 | key => 'id', 164 | facets => array[faceting.plain_facet('category_id')]); 165 | SELECT * FROM faceting.top_values('facetingtestsuite.documents'::regclass); 166 | -------------------------------------------------------------------------------- /test/sql/error_checks.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION IF NOT EXISTS roaringbitmap; 2 | CREATE EXTENSION IF NOT EXISTS pgfaceting; 3 | 4 | CREATE SCHEMA errorchecks; 5 | SET SEARCH_PATH = 'errorchecks', 'public'; 6 | 7 | CREATE TABLE uuid_based_docs ( 8 | id uuid primary key, 9 | type text 10 | ); 11 | 12 | CREATE TABLE text_based_docs ( 13 | id text primary key, 14 | type text 15 | ); 16 | 17 | CREATE TABLE int4_based_docs ( 18 | id int4 primary key, 19 | type text 20 | ); 21 | 22 | -- Expected error on key col not existing 23 | SELECT faceting.add_faceting_to_table('uuid_based_docs', 24 | key => 'nonexistent', 25 | facets => array[faceting.plain_facet('type')] 26 | ); 27 | 28 | -- Expected error on wrong type key column 29 | SELECT faceting.add_faceting_to_table('uuid_based_docs', 30 | key => 'id', 31 | facets => array[faceting.plain_facet('type')] 32 | ); 33 | SELECT faceting.add_faceting_to_table('text_based_docs', 34 | key => 'id', 35 | facets => array[faceting.plain_facet('type')] 36 | ); 37 | 38 | -- Wrong chunk bits 39 | SELECT faceting.add_faceting_to_table('int4_based_docs', 40 | key => 'id', 41 | chunk_bits => 42, 42 | facets => array[faceting.plain_facet('type')] 43 | ); 44 | 45 | -- Not faceted table 46 | SELECT faceting.add_facets('int4_based_docs', facets => array[faceting.plain_facet('type')]); 47 | 48 | -- Expected no error 49 | SELECT faceting.add_faceting_to_table('int4_based_docs', 50 | key => 'id', 51 | facets => array[faceting.plain_facet('type')] 52 | ); 53 | --------------------------------------------------------------------------------