postgresql/doc/src/sgml/hstore.sgml

327 lines
9.1 KiB
Plaintext
Raw Normal View History

<!-- $PostgreSQL: pgsql/doc/src/sgml/hstore.sgml,v 1.3 2009/03/15 22:05:17 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.
</para>
<para>
In the current implementation, neither the key nor the value
string can exceed 65535 bytes in length; an error will be thrown if this
limit is exceeded. These maximum lengths may change in future releases.
</para>
<sect2>
<title><type>hstore</> External Representation</title>
<para>
The text representation of an <type>hstore</> value includes zero
or more <replaceable>key</> <literal>=&gt;</> <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>=&gt;</> sign is ignored. Use double quotes if a key or
value includes whitespace, comma, <literal>=</> or <literal>&gt;</>.
To include a double quote or a backslash in a key or value, precede
it with another backslash. (Keep in mind that depending on the
setting of <varname>standard_conforming_strings</>, you may need to
double backslashes in SQL literal strings.)
</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>
<para>
Currently, 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>-&gt;</> <type>text</></entry>
<entry>get value for key (null if not present)</entry>
<entry><literal>'a=&gt;x, b=&gt;y'::hstore -&gt; 'a'</literal></entry>
<entry><literal>x</literal></entry>
</row>
<row>
<entry><type>text</> <literal>=&gt;</> <type>text</></entry>
<entry>make single-item <type>hstore</></entry>
<entry><literal>'a' =&gt; 'b'</literal></entry>
<entry><literal>"a"=&gt;"b"</literal></entry>
</row>
<row>
<entry><type>hstore</> <literal>||</> <type>hstore</></entry>
<entry>concatenation</entry>
<entry><literal>'a=&gt;b, c=&gt;d'::hstore || 'c=&gt;x, d=&gt;q'::hstore</literal></entry>
<entry><literal>"a"=&gt;"b", "c"=&gt;"x", "d"=&gt;"q"</literal></entry>
</row>
<row>
<entry><type>hstore</> <literal>?</> <type>text</></entry>
<entry>does <type>hstore</> contain key?</entry>
<entry><literal>'a=&gt;1'::hstore ? 'a'</literal></entry>
<entry><literal>t</literal></entry>
</row>
<row>
<entry><type>hstore</> <literal>@&gt;</> <type>hstore</></entry>
<entry>does left operand contain right?</entry>
<entry><literal>'a=&gt;b, b=&gt;1, c=&gt;NULL'::hstore @&gt; 'b=&gt;1'</literal></entry>
<entry><literal>t</literal></entry>
</row>
<row>
<entry><type>hstore</> <literal>&lt;@</> <type>hstore</></entry>
<entry>is left operand contained in right?</entry>
<entry><literal>'a=&gt;c'::hstore &lt;@ 'a=&gt;b, b=&gt;1, c=&gt;NULL'</literal></entry>
<entry><literal>f</literal></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
(Before PostgreSQL 8.2, the containment operators @&gt; and &lt;@ 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>akeys(hstore)</function></entry>
<entry><type>text[]</type></entry>
<entry>get <type>hstore</>'s keys as array</entry>
<entry><literal>akeys('a=&gt;1,b=&gt;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=&gt;1,b=&gt;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=&gt;1,b=&gt;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=&gt;1,b=&gt;2')</literal></entry>
<entry>
<programlisting>
1
2
</programlisting></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=&gt;1,b=&gt;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=&gt;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=&gt;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=&gt;1,b=&gt;2','b')</literal></entry>
<entry><literal>"a"=>"1"</literal></entry>
</row>
</tbody>
</tgroup>
</table>
</sect2>
<sect2>
<title>Indexes</title>
<para>
<type>hstore</> has index support for <literal>@&gt;</> 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>
</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>
</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>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>
</sect2>
</sect1>