2 F.17. hstore — hstore key/value datatype #
4 F.17.1. hstore External Representation
5 F.17.2. hstore Operators and Functions
13 This module implements the hstore data type for storing sets of
14 key/value pairs within a single PostgreSQL value. This can be useful in
15 various scenarios, such as rows with many attributes that are rarely
16 examined, or semi-structured data. Keys and values are simply text
19 This module is considered “trusted”, that is, it can be installed by
20 non-superusers who have CREATE privilege on the current database.
22 F.17.1. hstore External Representation #
24 The text representation of an hstore, used for input and output,
25 includes zero or more key => value pairs separated by commas. Some
28 foo => bar, baz => whatever
29 "1-a" => "anything at all"
31 The order of the pairs is not significant (and may not be reproduced on
32 output). Whitespace between pairs or around the => sign is ignored.
33 Double-quote keys and values that include whitespace, commas, =s or >s.
34 To include a double quote or a backslash in a key or value, escape it
37 Each key in an hstore is unique. If you declare an hstore with
38 duplicate keys, only one will be stored in the hstore and there is no
39 guarantee as to which will be kept:
40 SELECT 'a=>1,a=>2'::hstore;
45 A value (but not a key) can be an SQL NULL. For example:
48 The NULL keyword is case-insensitive. Double-quote the NULL to treat it
49 as the ordinary string “NULL”.
53 Keep in mind that the hstore text format, when used for input, applies
54 before any required quoting or escaping. If you are passing an hstore
55 literal via a parameter, then no additional processing is needed. But
56 if you're passing it as a quoted literal constant, then any
57 single-quote characters and (depending on the setting of the
58 standard_conforming_strings configuration parameter) backslash
59 characters need to be escaped correctly. See Section 4.1.2.1 for more
60 on the handling of string constants.
62 On output, double quotes always surround keys and values, even when
63 it's not strictly necessary.
65 F.17.2. hstore Operators and Functions #
67 The operators provided by the hstore module are shown in Table F.6, the
68 functions in Table F.7.
70 Table F.6. hstore Operators
80 Returns value associated with given key, or NULL if not present.
82 'a=>x, b=>y'::hstore -> 'a' → x
84 hstore -> text[] → text[]
86 Returns values associated with given keys, or NULL if not present.
88 'a=>x, b=>y, c=>z'::hstore -> ARRAY['c','a'] → {"z","x"}
90 hstore || hstore → hstore
92 Concatenates two hstores.
94 'a=>b, c=>d'::hstore || 'c=>x, d=>q'::hstore → "a"=>"b", "c"=>"x",
97 hstore ? text → boolean
99 Does hstore contain key?
101 'a=>1'::hstore ? 'a' → t
103 hstore ?& text[] → boolean
105 Does hstore contain all the specified keys?
107 'a=>1,b=>2'::hstore ?& ARRAY['a','b'] → t
109 hstore ?| text[] → boolean
111 Does hstore contain any of the specified keys?
113 'a=>1,b=>2'::hstore ?| ARRAY['b','c'] → t
115 hstore @> hstore → boolean
117 Does left operand contain right?
119 'a=>b, b=>1, c=>NULL'::hstore @> 'b=>1' → t
121 hstore <@ hstore → boolean
123 Is left operand contained in right?
125 'a=>c'::hstore <@ 'a=>b, b=>1, c=>NULL' → f
127 hstore - text → hstore
129 Deletes key from left operand.
131 'a=>1, b=>2, c=>3'::hstore - 'b'::text → "a"=>"1", "c"=>"3"
133 hstore - text[] → hstore
135 Deletes keys from left operand.
137 'a=>1, b=>2, c=>3'::hstore - ARRAY['a','b'] → "c"=>"3"
139 hstore - hstore → hstore
141 Deletes pairs from left operand that match pairs in the right operand.
143 'a=>1, b=>2, c=>3'::hstore - 'a=>4, b=>2'::hstore → "a"=>"1", "c"=>"3"
145 anyelement #= hstore → anyelement
147 Replaces fields in the left operand (which must be a composite type)
148 with matching values from hstore.
150 ROW(1,3) #= 'f1=>11'::hstore → (11,3)
154 Converts hstore to an array of alternating keys and values.
156 %% 'a=>foo, b=>bar'::hstore → {a,foo,b,bar}
160 Converts hstore to a two-dimensional key/value array.
162 %# 'a=>foo, b=>bar'::hstore → {{a,foo},{b,bar}}
164 Table F.7. hstore Functions
172 hstore ( record ) → hstore
174 Constructs an hstore from a record or row.
176 hstore(ROW(1,2)) → "f1"=>"1", "f2"=>"2"
178 hstore ( text[] ) → hstore
180 Constructs an hstore from an array, which may be either a key/value
181 array, or a two-dimensional array.
183 hstore(ARRAY['a','1','b','2']) → "a"=>"1", "b"=>"2"
185 hstore(ARRAY[['c','3'],['d','4']]) → "c"=>"3", "d"=>"4"
187 hstore ( text[], text[] ) → hstore
189 Constructs an hstore from separate key and value arrays.
191 hstore(ARRAY['a','b'], ARRAY['1','2']) → "a"=>"1", "b"=>"2"
193 hstore ( text, text ) → hstore
195 Makes a single-item hstore.
197 hstore('a', 'b') → "a"=>"b"
199 akeys ( hstore ) → text[]
201 Extracts an hstore's keys as an array.
203 akeys('a=>1,b=>2') → {a,b}
205 skeys ( hstore ) → setof text
207 Extracts an hstore's keys as a set.
213 avals ( hstore ) → text[]
215 Extracts an hstore's values as an array.
217 avals('a=>1,b=>2') → {1,2}
219 svals ( hstore ) → setof text
221 Extracts an hstore's values as a set.
227 hstore_to_array ( hstore ) → text[]
229 Extracts an hstore's keys and values as an array of alternating keys
232 hstore_to_array('a=>1,b=>2') → {a,1,b,2}
234 hstore_to_matrix ( hstore ) → text[]
236 Extracts an hstore's keys and values as a two-dimensional array.
238 hstore_to_matrix('a=>1,b=>2') → {{a,1},{b,2}}
240 hstore_to_json ( hstore ) → json
242 Converts an hstore to a json value, converting all non-null values to
245 This function is used implicitly when an hstore value is cast to json.
247 hstore_to_json('"a key"=>1, b=>t, c=>null, d=>12345, e=>012345,
248 f=>1.234, g=>2.345e+4') → {"a key": "1", "b": "t", "c": null, "d":
249 "12345", "e": "012345", "f": "1.234", "g": "2.345e+4"}
251 hstore_to_jsonb ( hstore ) → jsonb
253 Converts an hstore to a jsonb value, converting all non-null values to
256 This function is used implicitly when an hstore value is cast to jsonb.
258 hstore_to_jsonb('"a key"=>1, b=>t, c=>null, d=>12345, e=>012345,
259 f=>1.234, g=>2.345e+4') → {"a key": "1", "b": "t", "c": null, "d":
260 "12345", "e": "012345", "f": "1.234", "g": "2.345e+4"}
262 hstore_to_json_loose ( hstore ) → json
264 Converts an hstore to a json value, but attempts to distinguish
265 numerical and Boolean values so they are unquoted in the JSON.
267 hstore_to_json_loose('"a key"=>1, b=>t, c=>null, d=>12345, e=>012345,
268 f=>1.234, g=>2.345e+4') → {"a key": 1, "b": true, "c": null, "d":
269 12345, "e": "012345", "f": 1.234, "g": 2.345e+4}
271 hstore_to_jsonb_loose ( hstore ) → jsonb
273 Converts an hstore to a jsonb value, but attempts to distinguish
274 numerical and Boolean values so they are unquoted in the JSON.
276 hstore_to_jsonb_loose('"a key"=>1, b=>t, c=>null, d=>12345, e=>012345,
277 f=>1.234, g=>2.345e+4') → {"a key": 1, "b": true, "c": null, "d":
278 12345, "e": "012345", "f": 1.234, "g": 2.345e+4}
280 slice ( hstore, text[] ) → hstore
282 Extracts a subset of an hstore containing only the specified keys.
284 slice('a=>1,b=>2,c=>3'::hstore, ARRAY['b','c','x']) → "b"=>"2",
287 each ( hstore ) → setof record ( key text, value text )
289 Extracts an hstore's keys and values as a set of records.
291 select * from each('a=>1,b=>2') →
297 exist ( hstore, text ) → boolean
299 Does hstore contain key?
301 exist('a=>1', 'a') → t
303 defined ( hstore, text ) → boolean
305 Does hstore contain a non-NULL value for key?
307 defined('a=>NULL', 'a') → f
309 delete ( hstore, text ) → hstore
311 Deletes pair with matching key.
313 delete('a=>1,b=>2', 'b') → "a"=>"1"
315 delete ( hstore, text[] ) → hstore
317 Deletes pairs with matching keys.
319 delete('a=>1,b=>2,c=>3', ARRAY['a','b']) → "c"=>"3"
321 delete ( hstore, hstore ) → hstore
323 Deletes pairs matching those in the second argument.
325 delete('a=>1,b=>2', 'a=>4,b=>2'::hstore) → "a"=>"1"
327 populate_record ( anyelement, hstore ) → anyelement
329 Replaces fields in the left operand (which must be a composite type)
330 with matching values from hstore.
332 populate_record(ROW(1,2), 'f1=>42'::hstore) → (42,2)
334 In addition to these operators and functions, values of the hstore type
335 can be subscripted, allowing them to act like associative arrays. Only
336 a single subscript of type text can be specified; it is interpreted as
337 a key and the corresponding value is fetched or stored. For example,
338 CREATE TABLE mytable (h hstore);
339 INSERT INTO mytable VALUES ('a=>b, c=>d');
340 SELECT h['a'] FROM mytable;
346 UPDATE mytable SET h['c'] = 'new';
347 SELECT h FROM mytable;
349 ----------------------
353 A subscripted fetch returns NULL if the subscript is NULL or that key
354 does not exist in the hstore. (Thus, a subscripted fetch is not greatly
355 different from the -> operator.) A subscripted update fails if the
356 subscript is NULL; otherwise, it replaces the value for that key,
357 adding an entry to the hstore if the key does not already exist.
361 hstore has GiST and GIN index support for the @>, ?, ?& and ?|
362 operators. For example:
363 CREATE INDEX hidx ON testhstore USING GIST (h);
365 CREATE INDEX hidx ON testhstore USING GIN (h);
367 gist_hstore_ops GiST opclass approximates a set of key/value pairs as a
368 bitmap signature. Its optional integer parameter siglen determines the
369 signature length in bytes. The default length is 16 bytes. Valid values
370 of signature length are between 1 and 2024 bytes. Longer signatures
371 lead to a more precise search (scanning a smaller fraction of the index
372 and fewer heap pages), at the cost of a larger index.
374 Example of creating such an index with a signature length of 32 bytes:
375 CREATE INDEX hidx ON testhstore USING GIST (h gist_hstore_ops(siglen=32));
377 hstore also supports btree or hash indexes for the = operator. This
378 allows hstore columns to be declared UNIQUE, or to be used in GROUP BY,
379 ORDER BY or DISTINCT expressions. The sort ordering for hstore values
380 is not particularly useful, but these indexes may be useful for
381 equivalence lookups. Create indexes for = comparisons as follows:
382 CREATE INDEX hidx ON testhstore USING BTREE (h);
384 CREATE INDEX hidx ON testhstore USING HASH (h);
388 Add a key, or update an existing key with a new value:
389 UPDATE tab SET h['c'] = '3';
391 Another way to do the same thing is:
392 UPDATE tab SET h = h || hstore('c', '3');
394 If multiple keys are to be added or changed in one operation, the
395 concatenation approach is more efficient than subscripting:
396 UPDATE tab SET h = h || hstore(array['q', 'w'], array['11', '12']);
399 UPDATE tab SET h = delete(h, 'k1');
401 Convert a record to an hstore:
402 CREATE TABLE test (col1 integer, col2 text, col3 text);
403 INSERT INTO test VALUES (123, 'foo', 'bar');
405 SELECT hstore(t) FROM test AS t;
407 ---------------------------------------------
408 "col1"=>"123", "col2"=>"foo", "col3"=>"bar"
411 Convert an hstore to a predefined record type:
412 CREATE TABLE test (col1 integer, col2 text, col3 text);
414 SELECT * FROM populate_record(null::test,
415 '"col1"=>"456", "col2"=>"zzz"');
421 Modify an existing record using the values from an hstore:
422 CREATE TABLE test (col1 integer, col2 text, col3 text);
423 INSERT INTO test VALUES (123, 'foo', 'bar');
425 SELECT (r).* FROM (SELECT t #= '"col3"=>"baz"' AS r FROM test t) s;
433 The hstore type, because of its intrinsic liberality, could contain a
434 lot of different keys. Checking for valid keys is the task of the
435 application. The following examples demonstrate several techniques for
436 checking keys and obtaining statistics.
439 SELECT * FROM each('aaa=>bq, b=>NULL, ""=>1');
442 CREATE TABLE stat AS SELECT (each(h)).key, (each(h)).value FROM testhstore;
445 SELECT key, count(*) FROM
446 (SELECT (each(h)).key FROM testhstore) AS stat
448 ORDER BY count DESC, key;
462 F.17.6. Compatibility #
464 As of PostgreSQL 9.0, hstore uses a different internal representation
465 than previous versions. This presents no obstacle for dump/restore
466 upgrades since the text representation (used in the dump) is unchanged.
468 In the event of a binary upgrade, upward compatibility is maintained by
469 having the new code recognize old-format data. This will entail a
470 slight performance penalty when processing data that has not yet been
471 modified by the new code. It is possible to force an upgrade of all
472 values in a table column by doing an UPDATE statement as follows:
473 UPDATE tablename SET hstorecol = hstorecol || '';
475 Another way to do it is:
476 ALTER TABLE tablename ALTER hstorecol TYPE hstore USING hstorecol || '';
478 The ALTER TABLE method requires an ACCESS EXCLUSIVE lock on the table,
479 but does not result in bloating the table with old row versions.
483 Additional extensions are available that implement transforms for the
484 hstore type for the languages PL/Perl and PL/Python. The extensions for
485 PL/Perl are called hstore_plperl and hstore_plperlu, for trusted and
486 untrusted PL/Perl. If you install these transforms and specify them
487 when creating a function, hstore values are mapped to Perl hashes. The
488 extension for PL/Python is called hstore_plpython3u. If you use it,
489 hstore values are mapped to Python dictionaries.
493 Oleg Bartunov <oleg@sai.msu.su>, Moscow, Moscow University, Russia
495 Teodor Sigaev <teodor@sigaev.ru>, Moscow, Delta-Soft Ltd., Russia
497 Additional enhancements by Andrew Gierth <andrew@tao11.riddles.org.uk>,