mirror of
https://github.com/postgres/postgres.git
synced 2025-07-30 11:03:19 +03:00
Remove the 64K limit on the lengths of keys and values within an hstore. (This changes the on-disk format, but the old format can still be read.) Add support for btree/hash opclasses for hstore --- this is not so much for actual indexing purposes as to allow use of GROUP BY, DISTINCT, etc. Add various other new functions and operators. Andrew Gierth
577 lines
18 KiB
Plaintext
577 lines
18 KiB
Plaintext
<!-- $PostgreSQL: pgsql/doc/src/sgml/hstore.sgml,v 1.4 2009/09/30 19:50:22 tgl Exp $ -->
|
|
|
|
<sect1 id="hstore">
|
|
<title>hstore</title>
|
|
|
|
<indexterm zone="hstore">
|
|
<primary>hstore</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This module implements a data type <type>hstore</> for storing sets of
|
|
(key,value) pairs within a single <productname>PostgreSQL</> data field.
|
|
This can be useful in various scenarios, such as rows with many attributes
|
|
that are rarely examined, or semi-structured data. Keys and values are
|
|
arbitrary text strings.
|
|
</para>
|
|
|
|
<sect2>
|
|
<title><type>hstore</> External Representation</title>
|
|
|
|
<para>
|
|
The text representation of an <type>hstore</> value includes zero
|
|
or more <replaceable>key</> <literal>=></> <replaceable>value</>
|
|
items, separated by commas. For example:
|
|
|
|
<programlisting>
|
|
k => v
|
|
foo => bar, baz => whatever
|
|
"1-a" => "anything at all"
|
|
</programlisting>
|
|
|
|
The order of the items is not considered significant (and may not be
|
|
reproduced on output). Whitespace between items or around the
|
|
<literal>=></> sign is ignored. Use double quotes if a key or
|
|
value includes whitespace, comma, <literal>=</> or <literal>></>.
|
|
To include a double quote or a backslash in a key or value, precede
|
|
it with another backslash.
|
|
</para>
|
|
|
|
<para>
|
|
A value (but not a key) can be a SQL NULL. This is represented as
|
|
|
|
<programlisting>
|
|
key => NULL
|
|
</programlisting>
|
|
|
|
The <literal>NULL</> keyword is not case-sensitive. Again, use
|
|
double quotes if you want the string <literal>null</> to be treated
|
|
as an ordinary data value.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Keep in mind that the above format, when used to input hstore values,
|
|
applies <emphasis>before</> any required quoting or escaping. If you
|
|
are passing an hstore literal via a parameter, then no additional
|
|
processing is needed. If you are passing it as a quoted literal
|
|
constant, then any single-quote characters and (depending on the
|
|
setting of <varname>standard_conforming_strings</>) backslash characters
|
|
need to be escaped correctly. See <xref linkend="sql-syntax-strings">.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
Double quotes are always used to surround key and value
|
|
strings on output, even when this is not strictly necessary.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><type>hstore</> Operators and Functions</title>
|
|
|
|
<table id="hstore-op-table">
|
|
<title><type>hstore</> Operators</title>
|
|
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><type>hstore</> <literal>-></> <type>text</></entry>
|
|
<entry>get value for key (null if not present)</entry>
|
|
<entry><literal>'a=>x, b=>y'::hstore -> 'a'</literal></entry>
|
|
<entry><literal>x</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>-></> <type>text[]</></entry>
|
|
<entry>get values for keys (null if not present)</entry>
|
|
<entry><literal>'a=>x, b=>y, c=>z'::hstore -> ARRAY['c','a']</literal></entry>
|
|
<entry><literal>{"z","x"}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>text</> <literal>=></> <type>text</></entry>
|
|
<entry>make single-item <type>hstore</></entry>
|
|
<entry><literal>'a' => 'b'</literal></entry>
|
|
<entry><literal>"a"=>"b"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>text[]</> <literal>=></> <type>text[]</></entry>
|
|
<entry>construct an <type>hstore</> value from separate key and value arrays</entry>
|
|
<entry><literal>ARRAY['a','b'] => ARRAY['1','2']</literal></entry>
|
|
<entry><literal>"a"=>"1","b"=>"2"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>=></> <type>text[]</></entry>
|
|
<entry>extract a subset of an <type>hstore</> value</entry>
|
|
<entry><literal>'a=>1,b=>2,c=>3'::hstore => ARRAY['b','c','x']</literal></entry>
|
|
<entry><literal>"b"=>"2", "c"=>"3"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>||</> <type>hstore</></entry>
|
|
<entry>concatenation</entry>
|
|
<entry><literal>'a=>b, c=>d'::hstore || 'c=>x, d=>q'::hstore</literal></entry>
|
|
<entry><literal>"a"=>"b", "c"=>"x", "d"=>"q"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>?</> <type>text</></entry>
|
|
<entry>does <type>hstore</> contain key?</entry>
|
|
<entry><literal>'a=>1'::hstore ? 'a'</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>?&</> <type>text[]</></entry>
|
|
<entry>does <type>hstore</> contain all specified keys?</entry>
|
|
<entry><literal>'a=>1,b=>2'::hstore ?& ARRAY['a','b']</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>?|</> <type>text[]</></entry>
|
|
<entry>does <type>hstore</> contain any of the specified keys?</entry>
|
|
<entry><literal>'a=>1,b=>2'::hstore ?| ARRAY['b','c']</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>@></> <type>hstore</></entry>
|
|
<entry>does left operand contain right?</entry>
|
|
<entry><literal>'a=>b, b=>1, c=>NULL'::hstore @> 'b=>1'</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal><@</> <type>hstore</></entry>
|
|
<entry>is left operand contained in right?</entry>
|
|
<entry><literal>'a=>c'::hstore <@ 'a=>b, b=>1, c=>NULL'</literal></entry>
|
|
<entry><literal>f</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>-</> <type>text</></entry>
|
|
<entry>delete key from left operand</entry>
|
|
<entry><literal>'a=>1, b=>2, c=>3'::hstore - 'b'::text</literal></entry>
|
|
<entry><literal>"a"=>"1", "c"=>"3"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>-</> <type>text[]</></entry>
|
|
<entry>delete keys from left operand</entry>
|
|
<entry><literal>'a=>1, b=>2, c=>3'::hstore - ARRAY['a','b']</literal></entry>
|
|
<entry><literal>"c"=>"3"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>hstore</> <literal>-</> <type>hstore</></entry>
|
|
<entry>delete matching key/value pairs from left operand</entry>
|
|
<entry><literal>'a=>1, b=>2, c=>3'::hstore - 'a=>4, b=>2'::hstore</literal></entry>
|
|
<entry><literal>"a"=>"1", "c"=>"3"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>record</> <literal>#=</> <type>hstore</></entry>
|
|
<entry>replace fields in record with matching values from hstore</entry>
|
|
<entry>see Examples section</entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>%%</> <type>hstore</></entry>
|
|
<entry>convert hstore to array of alternating keys and values</entry>
|
|
<entry><literal>%% 'a=>foo, b=>bar'::hstore</literal></entry>
|
|
<entry><literal>{a,foo,b,bar}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>%#</> <type>hstore</></entry>
|
|
<entry>convert hstore to two-dimensional key/value array</entry>
|
|
<entry><literal>%# 'a=>foo, b=>bar'::hstore</literal></entry>
|
|
<entry><literal>{{a,foo},{b,bar}}</literal></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
(Before PostgreSQL 8.2, the containment operators @> and <@ were
|
|
respectively called @ and ~. These names are still available, but are
|
|
deprecated and will eventually be retired. Notice that the old names
|
|
are reversed from the convention formerly followed by the core geometric
|
|
datatypes!)
|
|
</para>
|
|
|
|
<table id="hstore-func-table">
|
|
<title><type>hstore</> Functions</title>
|
|
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><function>hstore(record)</function></entry>
|
|
<entry><type>hstore</type></entry>
|
|
<entry>construct an <type>hstore</> from a record or row</entry>
|
|
<entry><literal>hstore(ROW(1,2))</literal></entry>
|
|
<entry><literal>f1=>1,f2=>2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>hstore(text[])</function></entry>
|
|
<entry><type>hstore</type></entry>
|
|
<entry>construct an <type>hstore</> from an array, which may be either
|
|
a key/value array, or a two-dimensional array</entry>
|
|
<entry><literal>hstore(ARRAY['a','1','b','2']) || hstore(ARRAY[['c','3'],['d','4']])</literal></entry>
|
|
<entry><literal>a=>1, b=>2, c=>3, d=>4</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>akeys(hstore)</function></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>get <type>hstore</>'s keys as array</entry>
|
|
<entry><literal>akeys('a=>1,b=>2')</literal></entry>
|
|
<entry><literal>{a,b}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>skeys(hstore)</function></entry>
|
|
<entry><type>setof text</type></entry>
|
|
<entry>get <type>hstore</>'s keys as set</entry>
|
|
<entry><literal>skeys('a=>1,b=>2')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
a
|
|
b
|
|
</programlisting></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>avals(hstore)</function></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>get <type>hstore</>'s values as array</entry>
|
|
<entry><literal>avals('a=>1,b=>2')</literal></entry>
|
|
<entry><literal>{1,2}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>svals(hstore)</function></entry>
|
|
<entry><type>setof text</type></entry>
|
|
<entry>get <type>hstore</>'s values as set</entry>
|
|
<entry><literal>svals('a=>1,b=>2')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
1
|
|
2
|
|
</programlisting></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>hstore_to_array(hstore)</function></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>get <type>hstore</>'s keys and values as an array of alternating
|
|
keys and values</entry>
|
|
<entry><literal>hstore_to_array('a=>1,b=>2')</literal></entry>
|
|
<entry><literal>{a,1,b,2}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>hstore_to_matrix(hstore)</function></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>get <type>hstore</>'s keys and values as a two-dimensional array</entry>
|
|
<entry><literal>hstore_to_matrix('a=>1,b=>2')</literal></entry>
|
|
<entry><literal>{{a,1},{b,2}}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>each(hstore)</function></entry>
|
|
<entry><type>setof (key text, value text)</type></entry>
|
|
<entry>get <type>hstore</>'s keys and values as set</entry>
|
|
<entry><literal>select * from each('a=>1,b=>2')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
key | value
|
|
-----+-------
|
|
a | 1
|
|
b | 2
|
|
</programlisting></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>exist(hstore,text)</function></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does <type>hstore</> contain key?</entry>
|
|
<entry><literal>exist('a=>1','a')</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>defined(hstore,text)</function></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does <type>hstore</> contain non-null value for key?</entry>
|
|
<entry><literal>defined('a=>NULL','a')</literal></entry>
|
|
<entry><literal>f</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>delete(hstore,text)</function></entry>
|
|
<entry><type>hstore</type></entry>
|
|
<entry>delete any item matching key</entry>
|
|
<entry><literal>delete('a=>1,b=>2','b')</literal></entry>
|
|
<entry><literal>"a"=>"1"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>delete(hstore,text[])</function></entry>
|
|
<entry><type>hstore</type></entry>
|
|
<entry>delete any item matching any of the keys</entry>
|
|
<entry><literal>delete('a=>1,b=>2,c=>3',ARRAY['a','b'])</literal></entry>
|
|
<entry><literal>"c"=>"3"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>delete(hstore,hstore)</function></entry>
|
|
<entry><type>hstore</type></entry>
|
|
<entry>delete any key/value pair with an exact match in the second argument</entry>
|
|
<entry><literal>delete('a=>1,b=>2','a=>4,b=>2'::hstore)</literal></entry>
|
|
<entry><literal>"a"=>"1"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>populate_record(record,hstore)</function></entry>
|
|
<entry><type>record</type></entry>
|
|
<entry>replace fields in record with matching values from hstore</entry>
|
|
<entry>see Examples section</entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
The function <function>populate_record</function> is actually declared
|
|
with <type>anyelement</>, not <type>record</>, as its first argument;
|
|
but it will reject non-record types with a runtime error.
|
|
</para>
|
|
</note>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Indexes</title>
|
|
|
|
<para>
|
|
<type>hstore</> has index support for <literal>@></>, <literal>?</>,
|
|
<literal>?&</> and <literal>?|</> operators. You can use either
|
|
GiST or GIN index types. For example:
|
|
</para>
|
|
<programlisting>
|
|
CREATE INDEX hidx ON testhstore USING GIST (h);
|
|
|
|
CREATE INDEX hidx ON testhstore USING GIN (h);
|
|
</programlisting>
|
|
|
|
<para>
|
|
Additionally, <type>hstore</> has index support for the <literal>=</>
|
|
operator using the <type>btree</> or <type>hash</> index types. This
|
|
allows <type>hstore</> columns to be declared UNIQUE, or used with
|
|
GROUP BY, ORDER BY or DISTINCT. The sort ordering for <type>hstore</>
|
|
values is not intended to be particularly useful; it merely brings
|
|
exactly equal values together.
|
|
If an index is needed to support <literal>=</> comparisons it can be
|
|
created as follows:
|
|
</para>
|
|
<programlisting>
|
|
CREATE INDEX hidx ON testhstore USING BTREE (h);
|
|
|
|
CREATE INDEX hidx ON testhstore USING HASH (h);
|
|
</programlisting>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
Add a key, or update an existing key with a new value:
|
|
</para>
|
|
<programlisting>
|
|
UPDATE tab SET h = h || ('c' => '3');
|
|
</programlisting>
|
|
|
|
<para>
|
|
Delete a key:
|
|
</para>
|
|
<programlisting>
|
|
UPDATE tab SET h = delete(h, 'k1');
|
|
</programlisting>
|
|
|
|
<para>
|
|
Convert a record to an hstore:
|
|
</para>
|
|
<programlisting>
|
|
CREATE TABLE test (col1 integer, col2 text, col3 text);
|
|
INSERT INTO test VALUES (123, 'foo', 'bar');
|
|
|
|
SELECT hstore(t) FROM test AS t;
|
|
hstore
|
|
---------------------------------------------
|
|
"col1"=>"123", "col2"=>"foo", "col3"=>"bar"
|
|
(1 row)
|
|
</programlisting>
|
|
|
|
<para>
|
|
Convert an hstore to a predefined record type:
|
|
</para>
|
|
<programlisting>
|
|
CREATE TABLE test (col1 integer, col2 text, col3 text);
|
|
|
|
SELECT * FROM populate_record(null::test,
|
|
'"col1"=>"456", "col2"=>"zzz"');
|
|
col1 | col2 | col3
|
|
------+------+------
|
|
456 | zzz |
|
|
(1 row)
|
|
</programlisting>
|
|
|
|
<para>
|
|
Modify an existing record using the values from an hstore:
|
|
</para>
|
|
<programlisting>
|
|
CREATE TABLE test (col1 integer, col2 text, col3 text);
|
|
INSERT INTO test VALUES (123, 'foo', 'bar');
|
|
|
|
SELECT (r).* FROM (SELECT t #= '"col3"=>"baz"' AS r FROM test t) s;
|
|
col1 | col2 | col3
|
|
------+------+------
|
|
123 | foo | baz
|
|
(1 row)
|
|
</programlisting>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Statistics</title>
|
|
|
|
<para>
|
|
The <type>hstore</> type, because of its intrinsic liberality, could
|
|
contain a lot of different keys. Checking for valid keys is the task of the
|
|
application. Examples below demonstrate several techniques for checking
|
|
keys and obtaining statistics.
|
|
</para>
|
|
|
|
<para>
|
|
Simple example:
|
|
</para>
|
|
<programlisting>
|
|
SELECT * FROM each('aaa=>bq, b=>NULL, ""=>1');
|
|
</programlisting>
|
|
|
|
<para>
|
|
Using a table:
|
|
</para>
|
|
<programlisting>
|
|
SELECT (each(h)).key, (each(h)).value INTO stat FROM testhstore;
|
|
</programlisting>
|
|
|
|
<para>
|
|
Online statistics:
|
|
</para>
|
|
<programlisting>
|
|
SELECT key, count(*) FROM
|
|
(SELECT (each(h)).key FROM testhstore) AS stat
|
|
GROUP BY key
|
|
ORDER BY count DESC, key;
|
|
key | count
|
|
-----------+-------
|
|
line | 883
|
|
query | 207
|
|
pos | 203
|
|
node | 202
|
|
space | 197
|
|
status | 195
|
|
public | 194
|
|
title | 190
|
|
org | 189
|
|
...................
|
|
</programlisting>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
<emphasis>When upgrading from older versions, always load the new
|
|
version of this module into the database before restoring an old
|
|
dump. Otherwise, many new features will be unavailable.</emphasis>
|
|
</para>
|
|
|
|
<para>
|
|
As of PostgreSQL 8.5, <type>hstore</> uses a different internal
|
|
representation than previous versions. This presents no obstacle for
|
|
dump/restore upgrades since the text representation (used in the dump) is
|
|
unchanged.
|
|
</para>
|
|
|
|
<para>
|
|
In the event of doing a binary upgrade, upward
|
|
compatibility is maintained by having the new code recognize
|
|
old-format data. This will entail a slight performance penalty when
|
|
processing data that has not yet been modified by the new code. It is
|
|
possible to force an upgrade of all values in a table column
|
|
by doing an UPDATE statement as follows:
|
|
</para>
|
|
<programlisting>
|
|
UPDATE tablename SET hstorecol = hstorecol || '';
|
|
</programlisting>
|
|
|
|
<para>
|
|
Another way to do it is:
|
|
<programlisting>
|
|
ALTER TABLE tablename ALTER hstorecol TYPE hstore USING hstorecol || '';
|
|
</programlisting>
|
|
The <command>ALTER TABLE</> method requires an exclusive lock on the table,
|
|
but does not result in bloating the table with old row versions.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Authors</title>
|
|
|
|
<para>
|
|
Oleg Bartunov <email>oleg@sai.msu.su</email>, Moscow, Moscow University, Russia
|
|
</para>
|
|
|
|
<para>
|
|
Teodor Sigaev <email>teodor@sigaev.ru</email>, Moscow, Delta-Soft Ltd., Russia
|
|
</para>
|
|
|
|
<para>
|
|
Additional enhancements by Andrew Gierth <email>andrew@tao11.riddles.org.uk</email>, United Kingdom
|
|
</para>
|
|
</sect2>
|
|
|
|
</sect1>
|