aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/hstore.sgml
blob: 48664b2b25b0143d849b62277101d408a0dfb3bc (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
<!-- $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>