]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
Additional functions and operators for jsonb
[postgresql] / doc / src / sgml / func.sgml
1 <!-- doc/src/sgml/func.sgml -->
2
3  <chapter id="functions">
4   <title>Functions and Operators</title>
5
6   <indexterm zone="functions">
7    <primary>function</primary>
8   </indexterm>
9
10   <indexterm zone="functions">
11    <primary>operator</primary>
12   </indexterm>
13
14   <para>
15    <productname>PostgreSQL</productname> provides a large number of
16    functions and operators for the built-in data types.  Users can also
17    define their own functions and operators, as described in
18    <xref linkend="server-programming">.  The
19    <application>psql</application> commands <command>\df</command> and
20    <command>\do</command> can be used to list all
21    available functions and operators, respectively.
22   </para>
23
24   <para>
25    If you are concerned about portability then note that most of
26    the functions and operators described in this chapter, with the
27    exception of the most trivial arithmetic and comparison operators
28    and some explicitly marked functions, are not specified by the
29    <acronym>SQL</acronym> standard. Some of this extended functionality
30    is present in other <acronym>SQL</acronym> database management
31    systems, and in many cases this functionality is compatible and
32    consistent between the various implementations.  This chapter is also
33    not exhaustive;  additional functions appear in relevant sections of
34    the manual.
35   </para>
36
37
38   <sect1 id="functions-logical">
39    <title>Logical Operators</title>
40
41    <indexterm zone="functions-logical">
42     <primary>operator</primary>
43     <secondary>logical</secondary>
44    </indexterm>
45
46    <indexterm>
47     <primary>Boolean</primary>
48     <secondary>operators</secondary>
49     <see>operators, logical</see>
50    </indexterm>
51
52    <para>
53     The usual logical operators are available:
54
55     <indexterm>
56      <primary>AND (operator)</primary>
57     </indexterm>
58
59     <indexterm>
60      <primary>OR (operator)</primary>
61     </indexterm>
62
63     <indexterm>
64      <primary>NOT (operator)</primary>
65     </indexterm>
66
67     <indexterm>
68      <primary>conjunction</primary>
69     </indexterm>
70
71     <indexterm>
72      <primary>disjunction</primary>
73     </indexterm>
74
75     <indexterm>
76      <primary>negation</primary>
77     </indexterm>
78
79     <simplelist>
80      <member><literal>AND</></member>
81      <member><literal>OR</></member>
82      <member><literal>NOT</></member>
83     </simplelist>
84
85     <acronym>SQL</acronym> uses a three-valued logic system with true,
86     false, and <literal>null</>, which represents <quote>unknown</quote>.
87     Observe the following truth tables:
88
89     <informaltable>
90      <tgroup cols="4">
91       <thead>
92        <row>
93         <entry><replaceable>a</replaceable></entry>
94         <entry><replaceable>b</replaceable></entry>
95         <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
96         <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
97        </row>
98       </thead>
99
100       <tbody>
101        <row>
102         <entry>TRUE</entry>
103         <entry>TRUE</entry>
104         <entry>TRUE</entry>
105         <entry>TRUE</entry>
106        </row>
107
108        <row>
109         <entry>TRUE</entry>
110         <entry>FALSE</entry>
111         <entry>FALSE</entry>
112         <entry>TRUE</entry>
113        </row>
114
115        <row>
116         <entry>TRUE</entry>
117         <entry>NULL</entry>
118         <entry>NULL</entry>
119         <entry>TRUE</entry>
120        </row>
121
122        <row>
123         <entry>FALSE</entry>
124         <entry>FALSE</entry>
125         <entry>FALSE</entry>
126         <entry>FALSE</entry>
127        </row>
128
129        <row>
130         <entry>FALSE</entry>
131         <entry>NULL</entry>
132         <entry>FALSE</entry>
133         <entry>NULL</entry>
134        </row>
135
136        <row>
137         <entry>NULL</entry>
138         <entry>NULL</entry>
139         <entry>NULL</entry>
140         <entry>NULL</entry>
141        </row>
142       </tbody>
143      </tgroup>
144     </informaltable>
145
146     <informaltable>
147      <tgroup cols="2">
148       <thead>
149        <row>
150         <entry><replaceable>a</replaceable></entry>
151         <entry>NOT <replaceable>a</replaceable></entry>
152        </row>
153       </thead>
154
155       <tbody>
156        <row>
157         <entry>TRUE</entry>
158         <entry>FALSE</entry>
159        </row>
160
161        <row>
162         <entry>FALSE</entry>
163         <entry>TRUE</entry>
164        </row>
165
166        <row>
167         <entry>NULL</entry>
168         <entry>NULL</entry>
169        </row>
170       </tbody>
171      </tgroup>
172     </informaltable>
173    </para>
174
175    <para>
176     The operators <literal>AND</literal> and <literal>OR</literal> are
177     commutative, that is, you can switch the left and right operand
178     without affecting the result.  But see <xref
179     linkend="syntax-express-eval"> for more information about the
180     order of evaluation of subexpressions.
181    </para>
182   </sect1>
183
184   <sect1 id="functions-comparison">
185    <title>Comparison Operators</title>
186
187    <indexterm zone="functions-comparison">
188     <primary>comparison</primary>
189     <secondary>operators</secondary>
190    </indexterm>
191
192    <para>
193     The usual comparison operators are available, shown in <xref
194     linkend="functions-comparison-table">.
195    </para>
196
197    <table id="functions-comparison-table">
198     <title>Comparison Operators</title>
199     <tgroup cols="2">
200      <thead>
201       <row>
202        <entry>Operator</entry>
203        <entry>Description</entry>
204       </row>
205      </thead>
206
207      <tbody>
208       <row>
209        <entry> <literal>&lt;</literal> </entry>
210        <entry>less than</entry>
211       </row>
212
213       <row>
214        <entry> <literal>&gt;</literal> </entry>
215        <entry>greater than</entry>
216       </row>
217
218       <row>
219        <entry> <literal>&lt;=</literal> </entry>
220        <entry>less than or equal to</entry>
221       </row>
222
223       <row>
224        <entry> <literal>&gt;=</literal> </entry>
225        <entry>greater than or equal to</entry>
226       </row>
227
228       <row>
229        <entry> <literal>=</literal> </entry>
230        <entry>equal</entry>
231       </row>
232
233       <row>
234        <entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
235        <entry>not equal</entry>
236       </row>
237      </tbody>
238     </tgroup>
239    </table>
240
241    <note>
242     <para>
243      The <literal>!=</literal> operator is converted to
244      <literal>&lt;&gt;</literal> in the parser stage.  It is not
245      possible to implement <literal>!=</literal> and
246      <literal>&lt;&gt;</literal> operators that do different things.
247     </para>
248    </note>
249
250    <para>
251     Comparison operators are available for all relevant data types.
252     All comparison operators are binary operators that
253     return values of type <type>boolean</type>; expressions like
254     <literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
255     no <literal>&lt;</literal> operator to compare a Boolean value with
256     <literal>3</literal>).
257    </para>
258
259    <para>
260     <indexterm>
261      <primary>BETWEEN</primary>
262     </indexterm>
263     In addition to the comparison operators, the special
264     <token>BETWEEN</token> construct is available:
265 <synopsis>
266 <replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
267 </synopsis>
268     is equivalent to
269 <synopsis>
270 <replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
271 </synopsis>
272     Notice that <token>BETWEEN</token> treats the endpoint values as included
273     in the range.
274     <literal>NOT BETWEEN</literal> does the opposite comparison:
275 <synopsis>
276 <replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
277 </synopsis>
278     is equivalent to
279 <synopsis>
280 <replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
281 </synopsis>
282     <indexterm>
283      <primary>BETWEEN SYMMETRIC</primary>
284     </indexterm>
285     <literal>BETWEEN SYMMETRIC</> is the same as <literal>BETWEEN</>
286     except there is no requirement that the argument to the left of
287     <literal>AND</> be less than or equal to the argument on the right.
288     If it is not, those two arguments are automatically swapped, so that
289     a nonempty range is always implied.
290    </para>
291
292    <para>
293     <indexterm>
294      <primary>IS NULL</primary>
295     </indexterm>
296     <indexterm>
297      <primary>IS NOT NULL</primary>
298     </indexterm>
299     <indexterm>
300      <primary>ISNULL</primary>
301     </indexterm>
302     <indexterm>
303      <primary>NOTNULL</primary>
304     </indexterm>
305     To check whether a value is or is not null, use the constructs:
306 <synopsis>
307 <replaceable>expression</replaceable> IS NULL
308 <replaceable>expression</replaceable> IS NOT NULL
309 </synopsis>
310     or the equivalent, but nonstandard, constructs:
311 <synopsis>
312 <replaceable>expression</replaceable> ISNULL
313 <replaceable>expression</replaceable> NOTNULL
314 </synopsis>
315     <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
316    </para>
317
318    <para>
319     Do <emphasis>not</emphasis> write
320     <literal><replaceable>expression</replaceable> = NULL</literal>
321     because <literal>NULL</> is not <quote>equal to</quote>
322     <literal>NULL</>.  (The null value represents an unknown value,
323     and it is not known whether two unknown values are equal.) This
324     behavior conforms to the SQL standard.
325    </para>
326
327   <tip>
328    <para>
329     Some applications might expect that
330     <literal><replaceable>expression</replaceable> = NULL</literal>
331     returns true if <replaceable>expression</replaceable> evaluates to
332     the null value.  It is highly recommended that these applications
333     be modified to comply with the SQL standard. However, if that
334     cannot be done the <xref linkend="guc-transform-null-equals">
335     configuration variable is available. If it is enabled,
336     <productname>PostgreSQL</productname> will convert <literal>x =
337     NULL</literal> clauses to <literal>x IS NULL</literal>.
338    </para>
339   </tip>
340
341   <note>
342    <para>
343     If the <replaceable>expression</replaceable> is row-valued, then
344     <literal>IS NULL</> is true when the row expression itself is null
345     or when all the row's fields are null, while
346     <literal>IS NOT NULL</> is true when the row expression itself is non-null
347     and all the row's fields are non-null.  Because of this behavior,
348     <literal>IS NULL</> and <literal>IS NOT NULL</> do not always return
349     inverse results for row-valued expressions, i.e., a row-valued
350     expression that contains both NULL and non-null values will return false
351     for both tests.
352     This definition conforms to the SQL standard, and is a change from the
353     inconsistent behavior exhibited by <productname>PostgreSQL</productname>
354     versions prior to 8.2.
355    </para>
356   </note>
357
358    <para>
359     <indexterm>
360      <primary>IS DISTINCT FROM</primary>
361     </indexterm>
362     <indexterm>
363      <primary>IS NOT DISTINCT FROM</primary>
364     </indexterm>
365     Ordinary comparison operators yield null (signifying <quote>unknown</>),
366     not true or false, when either input is null.  For example,
367     <literal>7 = NULL</> yields null, as does <literal>7 &lt;&gt; NULL</>.  When
368     this behavior is not suitable, use the
369     <literal>IS <optional> NOT </> DISTINCT FROM</literal> constructs:
370 <synopsis>
371 <replaceable>expression</replaceable> IS DISTINCT FROM <replaceable>expression</replaceable>
372 <replaceable>expression</replaceable> IS NOT DISTINCT FROM <replaceable>expression</replaceable>
373 </synopsis>
374     For non-null inputs, <literal>IS DISTINCT FROM</literal> is
375     the same as the <literal>&lt;&gt;</> operator.  However, if both
376     inputs are null it returns false, and if only one input is
377     null it returns true.  Similarly, <literal>IS NOT DISTINCT
378     FROM</literal> is identical to <literal>=</literal> for non-null
379     inputs, but it returns true when both inputs are null, and false when only
380     one input is null. Thus, these constructs effectively act as though null
381     were a normal data value, rather than <quote>unknown</>.
382    </para>
383
384    <para>
385     <indexterm>
386      <primary>IS TRUE</primary>
387     </indexterm>
388     <indexterm>
389      <primary>IS NOT TRUE</primary>
390     </indexterm>
391     <indexterm>
392      <primary>IS FALSE</primary>
393     </indexterm>
394     <indexterm>
395      <primary>IS NOT FALSE</primary>
396     </indexterm>
397     <indexterm>
398      <primary>IS UNKNOWN</primary>
399     </indexterm>
400     <indexterm>
401      <primary>IS NOT UNKNOWN</primary>
402     </indexterm>
403     Boolean values can also be tested using the constructs
404 <synopsis>
405 <replaceable>expression</replaceable> IS TRUE
406 <replaceable>expression</replaceable> IS NOT TRUE
407 <replaceable>expression</replaceable> IS FALSE
408 <replaceable>expression</replaceable> IS NOT FALSE
409 <replaceable>expression</replaceable> IS UNKNOWN
410 <replaceable>expression</replaceable> IS NOT UNKNOWN
411 </synopsis>
412     These will always return true or false, never a null value, even when the
413     operand is null.
414     A null input is treated as the logical value <quote>unknown</>.
415     Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
416     effectively the same as <literal>IS NULL</literal> and
417     <literal>IS NOT NULL</literal>, respectively, except that the input
418     expression must be of Boolean type.
419    </para>
420
421 <!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
422    <para>
423     <indexterm>
424      <primary>IS OF</primary>
425     </indexterm>
426     <indexterm>
427      <primary>IS NOT OF</primary>
428     </indexterm>
429     It is possible to check the data type of an expression using the
430     constructs
431 <synopsis>
432 <replaceable>expression</replaceable> IS OF (typename, ...)
433 <replaceable>expression</replaceable> IS NOT OF (typename, ...)
434 </synopsis>
435     They return a boolean value based on whether the expression's data
436     type is one of the listed data types.
437    </para>
438 -->
439
440   </sect1>
441
442   <sect1 id="functions-math">
443    <title>Mathematical Functions and Operators</title>
444
445    <para>
446     Mathematical operators are provided for many
447     <productname>PostgreSQL</productname> types. For types without
448     standard mathematical conventions
449     (e.g., date/time types) we
450     describe the actual behavior in subsequent sections.
451    </para>
452
453    <para>
454     <xref linkend="functions-math-op-table"> shows the available mathematical operators.
455    </para>
456
457    <table id="functions-math-op-table">
458     <title>Mathematical Operators</title>
459
460     <tgroup cols="4">
461      <thead>
462       <row>
463        <entry>Operator</entry>
464        <entry>Description</entry>
465        <entry>Example</entry>
466        <entry>Result</entry>
467       </row>
468      </thead>
469
470      <tbody>
471       <row>
472        <entry> <literal>+</literal> </entry>
473        <entry>addition</entry>
474        <entry><literal>2 + 3</literal></entry>
475        <entry><literal>5</literal></entry>
476       </row>
477
478       <row>
479        <entry> <literal>-</literal> </entry>
480        <entry>subtraction</entry>
481        <entry><literal>2 - 3</literal></entry>
482        <entry><literal>-1</literal></entry>
483       </row>
484
485       <row>
486        <entry> <literal>*</literal> </entry>
487        <entry>multiplication</entry>
488        <entry><literal>2 * 3</literal></entry>
489        <entry><literal>6</literal></entry>
490       </row>
491
492       <row>
493        <entry> <literal>/</literal> </entry>
494        <entry>division (integer division truncates the result)</entry>
495        <entry><literal>4 / 2</literal></entry>
496        <entry><literal>2</literal></entry>
497       </row>
498
499       <row>
500        <entry> <literal>%</literal> </entry>
501        <entry>modulo (remainder)</entry>
502        <entry><literal>5 % 4</literal></entry>
503        <entry><literal>1</literal></entry>
504       </row>
505
506       <row>
507        <entry> <literal>^</literal> </entry>
508        <entry>exponentiation</entry>
509        <entry><literal>2.0 ^ 3.0</literal></entry>
510        <entry><literal>8</literal></entry>
511       </row>
512
513       <row>
514        <entry> <literal>|/</literal> </entry>
515        <entry>square root</entry>
516        <entry><literal>|/ 25.0</literal></entry>
517        <entry><literal>5</literal></entry>
518       </row>
519
520       <row>
521        <entry> <literal>||/</literal> </entry>
522        <entry>cube root</entry>
523        <entry><literal>||/ 27.0</literal></entry>
524        <entry><literal>3</literal></entry>
525       </row>
526
527       <row>
528        <entry> <literal>!</literal> </entry>
529        <entry>factorial</entry>
530        <entry><literal>5 !</literal></entry>
531        <entry><literal>120</literal></entry>
532       </row>
533
534       <row>
535        <entry> <literal>!!</literal> </entry>
536        <entry>factorial (prefix operator)</entry>
537        <entry><literal>!! 5</literal></entry>
538        <entry><literal>120</literal></entry>
539       </row>
540
541       <row>
542        <entry> <literal>@</literal> </entry>
543        <entry>absolute value</entry>
544        <entry><literal>@ -5.0</literal></entry>
545        <entry><literal>5</literal></entry>
546       </row>
547
548       <row>
549        <entry> <literal>&amp;</literal> </entry>
550        <entry>bitwise AND</entry>
551        <entry><literal>91 &amp; 15</literal></entry>
552        <entry><literal>11</literal></entry>
553       </row>
554
555       <row>
556        <entry> <literal>|</literal> </entry>
557        <entry>bitwise OR</entry>
558        <entry><literal>32 | 3</literal></entry>
559        <entry><literal>35</literal></entry>
560       </row>
561
562       <row>
563        <entry> <literal>#</literal> </entry>
564        <entry>bitwise XOR</entry>
565        <entry><literal>17 # 5</literal></entry>
566        <entry><literal>20</literal></entry>
567       </row>
568
569       <row>
570        <entry> <literal>~</literal> </entry>
571        <entry>bitwise NOT</entry>
572        <entry><literal>~1</literal></entry>
573        <entry><literal>-2</literal></entry>
574       </row>
575
576       <row>
577        <entry> <literal>&lt;&lt;</literal> </entry>
578        <entry>bitwise shift left</entry>
579        <entry><literal>1 &lt;&lt; 4</literal></entry>
580        <entry><literal>16</literal></entry>
581       </row>
582
583       <row>
584        <entry> <literal>&gt;&gt;</literal> </entry>
585        <entry>bitwise shift right</entry>
586        <entry><literal>8 &gt;&gt; 2</literal></entry>
587        <entry><literal>2</literal></entry>
588       </row>
589
590      </tbody>
591     </tgroup>
592    </table>
593
594    <para>
595     The bitwise operators work only on integral data types, whereas
596     the others are available for all numeric data types.  The bitwise
597     operators are also available for the bit
598     string types <type>bit</type> and <type>bit varying</type>, as
599     shown in <xref linkend="functions-bit-string-op-table">.
600    </para>
601
602   <para>
603    <xref linkend="functions-math-func-table"> shows the available
604    mathematical functions.  In the table, <literal>dp</literal>
605    indicates <type>double precision</type>.  Many of these functions
606    are provided in multiple forms with different argument types.
607    Except where noted, any given form of a function returns the same
608    data type as its argument.
609    The functions working with <type>double precision</type> data are mostly
610    implemented on top of the host system's C library; accuracy and behavior in
611    boundary cases can therefore vary depending on the host system.
612   </para>
613
614    <table id="functions-math-func-table">
615     <title>Mathematical Functions</title>
616     <tgroup cols="5">
617      <thead>
618       <row>
619        <entry>Function</entry>
620        <entry>Return Type</entry>
621        <entry>Description</entry>
622        <entry>Example</entry>
623        <entry>Result</entry>
624       </row>
625      </thead>
626
627      <tbody>
628       <row>
629        <entry>
630         <indexterm>
631          <primary>abs</primary>
632         </indexterm>
633         <literal><function>abs(<replaceable>x</replaceable>)</function></literal>
634        </entry>
635        <entry>(same as input)</entry>
636        <entry>absolute value</entry>
637        <entry><literal>abs(-17.4)</literal></entry>
638        <entry><literal>17.4</literal></entry>
639       </row>
640
641       <row>
642        <entry>
643         <indexterm>
644          <primary>cbrt</primary>
645         </indexterm>
646         <literal><function>cbrt(<type>dp</type>)</function></literal>
647        </entry>
648        <entry><type>dp</type></entry>
649        <entry>cube root</entry>
650        <entry><literal>cbrt(27.0)</literal></entry>
651        <entry><literal>3</literal></entry>
652       </row>
653
654       <row>
655        <entry>
656         <indexterm>
657          <primary>ceil</primary>
658         </indexterm>
659         <literal><function>ceil(<type>dp</type> or <type>numeric</type>)</function></literal>
660        </entry>
661        <entry>(same as input)</entry>
662        <entry>smallest integer not less than argument</entry>
663        <entry><literal>ceil(-42.8)</literal></entry>
664        <entry><literal>-42</literal></entry>
665       </row>
666
667       <row>
668        <entry>
669         <indexterm>
670          <primary>ceiling</primary>
671         </indexterm>
672         <literal><function>ceiling(<type>dp</type> or <type>numeric</type>)</function></literal>
673        </entry>
674        <entry>(same as input)</entry>
675        <entry>smallest integer not less than argument (alias for <function>ceil</function>)</entry>
676        <entry><literal>ceiling(-95.3)</literal></entry>
677        <entry><literal>-95</literal></entry>
678       </row>
679
680       <row>
681        <entry>
682         <indexterm>
683          <primary>degrees</primary>
684         </indexterm>
685         <literal><function>degrees(<type>dp</type>)</function></literal>
686        </entry>
687        <entry><type>dp</type></entry>
688        <entry>radians to degrees</entry>
689        <entry><literal>degrees(0.5)</literal></entry>
690        <entry><literal>28.6478897565412</literal></entry>
691       </row>
692
693       <row>
694        <entry>
695         <indexterm>
696          <primary>div</primary>
697         </indexterm>
698         <literal><function>div(<parameter>y</parameter> <type>numeric</>,
699          <parameter>x</parameter> <type>numeric</>)</function></literal>
700        </entry>
701        <entry><type>numeric</></entry>
702        <entry>integer quotient of <parameter>y</parameter>/<parameter>x</parameter></entry>
703        <entry><literal>div(9,4)</literal></entry>
704        <entry><literal>2</literal></entry>
705       </row>
706
707       <row>
708        <entry>
709         <indexterm>
710          <primary>exp</primary>
711         </indexterm>
712         <literal><function>exp(<type>dp</type> or <type>numeric</type>)</function></literal>
713        </entry>
714        <entry>(same as input)</entry>
715        <entry>exponential</entry>
716        <entry><literal>exp(1.0)</literal></entry>
717        <entry><literal>2.71828182845905</literal></entry>
718       </row>
719
720       <row>
721        <entry>
722         <indexterm>
723          <primary>floor</primary>
724         </indexterm>
725         <literal><function>floor(<type>dp</type> or <type>numeric</type>)</function></literal>
726        </entry>
727        <entry>(same as input)</entry>
728        <entry>largest integer not greater than argument</entry>
729        <entry><literal>floor(-42.8)</literal></entry>
730        <entry><literal>-43</literal></entry>
731       </row>
732
733       <row>
734        <entry>
735         <indexterm>
736          <primary>ln</primary>
737         </indexterm>
738         <literal><function>ln(<type>dp</type> or <type>numeric</type>)</function></literal>
739        </entry>
740        <entry>(same as input)</entry>
741        <entry>natural logarithm</entry>
742        <entry><literal>ln(2.0)</literal></entry>
743        <entry><literal>0.693147180559945</literal></entry>
744       </row>
745
746       <row>
747        <entry>
748         <indexterm>
749          <primary>log</primary>
750         </indexterm>
751         <literal><function>log(<type>dp</type> or <type>numeric</type>)</function></literal>
752        </entry>
753        <entry>(same as input)</entry>
754        <entry>base 10 logarithm</entry>
755        <entry><literal>log(100.0)</literal></entry>
756        <entry><literal>2</literal></entry>
757       </row>
758
759       <row>
760        <entry><literal><function>log(<parameter>b</parameter> <type>numeric</type>,
761         <parameter>x</parameter> <type>numeric</type>)</function></literal></entry>
762        <entry><type>numeric</type></entry>
763        <entry>logarithm to base <parameter>b</parameter></entry>
764        <entry><literal>log(2.0, 64.0)</literal></entry>
765        <entry><literal>6.0000000000</literal></entry>
766       </row>
767
768       <row>
769        <entry>
770         <indexterm>
771          <primary>mod</primary>
772         </indexterm>
773         <literal><function>mod(<parameter>y</parameter>,
774          <parameter>x</parameter>)</function></literal>
775        </entry>
776        <entry>(same as argument types)</entry>
777        <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
778        <entry><literal>mod(9,4)</literal></entry>
779        <entry><literal>1</literal></entry>
780       </row>
781
782       <row>
783        <entry>
784         <indexterm>
785          <primary>pi</primary>
786         </indexterm>
787         <literal><function>pi()</function></literal>
788        </entry>
789        <entry><type>dp</type></entry>
790        <entry><quote>&pi;</quote> constant</entry>
791        <entry><literal>pi()</literal></entry>
792        <entry><literal>3.14159265358979</literal></entry>
793       </row>
794
795       <row>
796        <entry>
797         <indexterm>
798          <primary>power</primary>
799         </indexterm>
800         <literal><function>power(<parameter>a</parameter> <type>dp</type>,
801         <parameter>b</parameter> <type>dp</type>)</function></literal>
802        </entry>
803        <entry><type>dp</type></entry>
804        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
805        <entry><literal>power(9.0, 3.0)</literal></entry>
806        <entry><literal>729</literal></entry>
807       </row>
808
809       <row>
810        <entry><literal><function>power(<parameter>a</parameter> <type>numeric</type>,
811         <parameter>b</parameter> <type>numeric</type>)</function></literal></entry>
812        <entry><type>numeric</type></entry>
813        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
814        <entry><literal>power(9.0, 3.0)</literal></entry>
815        <entry><literal>729</literal></entry>
816       </row>
817
818       <row>
819        <entry>
820         <indexterm>
821          <primary>radians</primary>
822         </indexterm>
823         <literal><function>radians(<type>dp</type>)</function></literal>
824        </entry>
825        <entry><type>dp</type></entry>
826        <entry>degrees to radians</entry>
827        <entry><literal>radians(45.0)</literal></entry>
828        <entry><literal>0.785398163397448</literal></entry>
829       </row>
830
831       <row>
832        <entry>
833         <indexterm>
834          <primary>round</primary>
835         </indexterm>
836         <literal><function>round(<type>dp</type> or <type>numeric</type>)</function></literal>
837        </entry>
838        <entry>(same as input)</entry>
839        <entry>round to nearest integer</entry>
840        <entry><literal>round(42.4)</literal></entry>
841        <entry><literal>42</literal></entry>
842       </row>
843
844       <row>
845        <entry><literal><function>round(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
846        <entry><type>numeric</type></entry>
847        <entry>round to <parameter>s</parameter> decimal places</entry>
848        <entry><literal>round(42.4382, 2)</literal></entry>
849        <entry><literal>42.44</literal></entry>
850       </row>
851
852       <row>
853        <entry>
854         <indexterm>
855          <primary>sign</primary>
856         </indexterm>
857         <literal><function>sign(<type>dp</type> or <type>numeric</type>)</function></literal>
858        </entry>
859        <entry>(same as input)</entry>
860        <entry>sign of the argument (-1, 0, +1)</entry>
861        <entry><literal>sign(-8.4)</literal></entry>
862        <entry><literal>-1</literal></entry>
863       </row>
864
865       <row>
866        <entry>
867         <indexterm>
868          <primary>sqrt</primary>
869         </indexterm>
870         <literal><function>sqrt(<type>dp</type> or <type>numeric</type>)</function></literal>
871        </entry>
872        <entry>(same as input)</entry>
873        <entry>square root</entry>
874        <entry><literal>sqrt(2.0)</literal></entry>
875        <entry><literal>1.4142135623731</literal></entry>
876       </row>
877
878       <row>
879        <entry>
880         <indexterm>
881          <primary>trunc</primary>
882         </indexterm>
883         <literal><function>trunc(<type>dp</type> or <type>numeric</type>)</function></literal>
884        </entry>
885        <entry>(same as input)</entry>
886        <entry>truncate toward zero</entry>
887        <entry><literal>trunc(42.8)</literal></entry>
888        <entry><literal>42</literal></entry>
889       </row>
890
891       <row>
892        <entry><literal><function>trunc(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
893        <entry><type>numeric</type></entry>
894        <entry>truncate to <parameter>s</parameter> decimal places</entry>
895        <entry><literal>trunc(42.4382, 2)</literal></entry>
896        <entry><literal>42.43</literal></entry>
897       </row>
898
899       <row>
900        <entry>
901         <indexterm>
902          <primary>width_bucket</primary>
903         </indexterm>
904         <literal><function>width_bucket(<parameter>operand</parameter> <type>dp</type>, <parameter>b1</parameter> <type>dp</type>, <parameter>b2</parameter> <type>dp</type>, <parameter>count</parameter> <type>int</type>)</function></literal></entry>
905        <entry><type>int</type></entry>
906        <entry>return the bucket number to which <parameter>operand</> would
907        be assigned in a histogram having <parameter>count</> equal-width
908        buckets spanning the range <parameter>b1</> to <parameter>b2</>;
909        returns <literal>0</> or <literal><parameter>count</>+1</literal> for
910        an input outside the range</entry>
911        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
912        <entry><literal>3</literal></entry>
913       </row>
914
915       <row>
916        <entry><literal><function>width_bucket(<parameter>operand</parameter> <type>numeric</type>, <parameter>b1</parameter> <type>numeric</type>, <parameter>b2</parameter> <type>numeric</type>, <parameter>count</parameter> <type>int</type>)</function></literal></entry>
917        <entry><type>int</type></entry>
918        <entry>return the bucket number to which <parameter>operand</> would
919        be assigned in a histogram having <parameter>count</> equal-width
920        buckets spanning the range <parameter>b1</> to <parameter>b2</>;
921        returns <literal>0</> or <literal><parameter>count</>+1</literal> for
922        an input outside the range</entry>
923        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
924        <entry><literal>3</literal></entry>
925       </row>
926
927       <row>
928        <entry><literal><function>width_bucket(<parameter>operand</parameter> <type>anyelement</type>, <parameter>thresholds</parameter> <type>anyarray</type>)</function></literal></entry>
929        <entry><type>int</type></entry>
930        <entry>return the bucket number to which <parameter>operand</> would
931        be assigned given an array listing the lower bounds of the buckets;
932        returns <literal>0</> for an input less than the first lower bound;
933        the <parameter>thresholds</> array <emphasis>must be sorted</>,
934        smallest first, or unexpected results will be obtained</entry>
935        <entry><literal>width_bucket(now(), array['yesterday', 'today', 'tomorrow']::timestamptz[])</literal></entry>
936        <entry><literal>2</literal></entry>
937       </row>
938      </tbody>
939     </tgroup>
940    </table>
941
942   <para>
943     <xref linkend="functions-math-random-table"> shows functions for
944     generating random numbers.
945   </para>
946
947    <table id="functions-math-random-table">
948     <title>Random Functions</title>
949
950     <tgroup cols="3">
951      <thead>
952       <row>
953        <entry>Function</entry>
954        <entry>Return Type</entry>
955        <entry>Description</entry>
956       </row>
957      </thead>
958      <tbody>
959       <row>
960        <entry>
961         <indexterm>
962          <primary>random</primary>
963         </indexterm>
964         <literal><function>random()</function></literal>
965        </entry>
966        <entry><type>dp</type></entry>
967        <entry>random value in the range 0.0 &lt;= x &lt; 1.0</entry>
968       </row>
969
970       <row>
971        <entry>
972         <indexterm>
973          <primary>setseed</primary>
974         </indexterm>
975         <literal><function>setseed(<type>dp</type>)</function></literal>
976        </entry>
977        <entry><type>void</type></entry>
978        <entry>set seed for subsequent <literal>random()</literal> calls (value between -1.0 and
979        1.0, inclusive)</entry>
980       </row>
981      </tbody>
982     </tgroup>
983    </table>
984
985   <para>
986    The characteristics of the values returned by
987    <literal><function>random()</function></literal> depend
988    on the system implementation. It is not suitable for cryptographic
989    applications; see <xref linkend="pgcrypto"> module for an alternative.
990    </para>
991
992   <para>
993    Finally, <xref linkend="functions-math-trig-table"> shows the
994    available trigonometric functions.  All trigonometric functions
995    take arguments and return values of type <type>double
996    precision</type>. Trigonometric functions arguments are expressed
997    in radians. Inverse functions return values are expressed in
998    radians.  See unit transformation functions
999    <literal><function>radians()</function></literal> and
1000    <literal><function>degrees()</function></literal> above.
1001   </para>
1002
1003    <table id="functions-math-trig-table">
1004     <title>Trigonometric Functions</title>
1005
1006     <tgroup cols="2">
1007      <thead>
1008       <row>
1009        <entry>Function</entry>
1010        <entry>Description</entry>
1011       </row>
1012      </thead>
1013
1014      <tbody>
1015       <row>
1016        <entry>
1017         <indexterm>
1018          <primary>acos</primary>
1019         </indexterm><literal><function>acos(<replaceable>x</replaceable>)</function></literal>
1020        </entry>
1021        <entry>inverse cosine</entry>
1022       </row>
1023
1024       <row>
1025        <entry>
1026         <indexterm>
1027          <primary>asin</primary>
1028         </indexterm>
1029         <literal><function>asin(<replaceable>x</replaceable>)</function></literal>
1030        </entry>
1031        <entry>inverse sine</entry>
1032       </row>
1033
1034       <row>
1035        <entry>
1036         <indexterm>
1037          <primary>atan</primary>
1038         </indexterm>
1039         <literal><function>atan(<replaceable>x</replaceable>)</function></literal>
1040        </entry>
1041        <entry>inverse tangent</entry>
1042       </row>
1043
1044       <row>
1045        <entry>
1046         <indexterm>
1047          <primary>atan2</primary>
1048         </indexterm>
1049         <literal><function>atan2(<replaceable>y</replaceable>,
1050         <replaceable>x</replaceable>)</function></literal>
1051        </entry>
1052        <entry>inverse tangent of
1053         <literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
1054       </row>
1055
1056       <row>
1057        <entry>
1058         <indexterm>
1059          <primary>cos</primary>
1060         </indexterm>
1061         <literal><function>cos(<replaceable>x</replaceable>)</function></literal>
1062        </entry>
1063        <entry>cosine</entry>
1064       </row>
1065
1066       <row>
1067        <entry>
1068         <indexterm>
1069          <primary>cot</primary>
1070         </indexterm>
1071         <literal><function>cot(<replaceable>x</replaceable>)</function></literal>
1072        </entry>
1073        <entry>cotangent</entry>
1074       </row>
1075
1076       <row>
1077        <entry>
1078         <indexterm>
1079          <primary>sin</primary>
1080         </indexterm>
1081         <literal><function>sin(<replaceable>x</replaceable>)</function></literal>
1082        </entry>
1083        <entry>sine</entry>
1084       </row>
1085
1086       <row>
1087        <entry>
1088         <indexterm>
1089          <primary>tan</primary>
1090         </indexterm>
1091         <literal><function>tan(<replaceable>x</replaceable>)</function></literal>
1092        </entry>
1093        <entry>tangent</entry>
1094       </row>
1095      </tbody>
1096     </tgroup>
1097    </table>
1098
1099   </sect1>
1100
1101
1102   <sect1 id="functions-string">
1103    <title>String Functions and Operators</title>
1104
1105    <para>
1106     This section describes functions and operators for examining and
1107     manipulating string values.  Strings in this context include values
1108     of the types <type>character</type>, <type>character varying</type>,
1109     and <type>text</type>.  Unless otherwise noted, all
1110     of the functions listed below work on all of these types, but be
1111     wary of potential effects of automatic space-padding when using the
1112     <type>character</type> type.  Some functions also exist
1113     natively for the bit-string types.
1114    </para>
1115
1116    <para>
1117     <acronym>SQL</acronym> defines some string functions that use
1118     key words, rather than commas, to separate
1119     arguments.  Details are in
1120     <xref linkend="functions-string-sql">.
1121     <productname>PostgreSQL</> also provides versions of these functions
1122     that use the regular function invocation syntax
1123     (see <xref linkend="functions-string-other">).
1124    </para>
1125
1126    <note>
1127     <para>
1128      Before <productname>PostgreSQL</productname> 8.3, these functions would
1129      silently accept values of several non-string data types as well, due to
1130      the presence of implicit coercions from those data types to
1131      <type>text</>.  Those coercions have been removed because they frequently
1132      caused surprising behaviors.  However, the string concatenation operator
1133      (<literal>||</>) still accepts non-string input, so long as at least one
1134      input is of a string type, as shown in <xref
1135      linkend="functions-string-sql">.  For other cases, insert an explicit
1136      coercion to <type>text</> if you need to duplicate the previous behavior.
1137     </para>
1138    </note>
1139
1140    <table id="functions-string-sql">
1141     <title><acronym>SQL</acronym> String Functions and Operators</title>
1142     <tgroup cols="5">
1143      <thead>
1144       <row>
1145        <entry>Function</entry>
1146        <entry>Return Type</entry>
1147        <entry>Description</entry>
1148        <entry>Example</entry>
1149        <entry>Result</entry>
1150       </row>
1151      </thead>
1152
1153      <tbody>
1154       <row>
1155        <entry><literal><parameter>string</parameter> <literal>||</literal>
1156         <parameter>string</parameter></literal></entry>
1157        <entry> <type>text</type> </entry>
1158        <entry>
1159         String concatenation
1160         <indexterm>
1161          <primary>character string</primary>
1162          <secondary>concatenation</secondary>
1163         </indexterm>
1164        </entry>
1165        <entry><literal>'Post' || 'greSQL'</literal></entry>
1166        <entry><literal>PostgreSQL</literal></entry>
1167       </row>
1168
1169       <row>
1170        <entry>
1171         <literal><parameter>string</parameter> <literal>||</literal>
1172         <parameter>non-string</parameter></literal>
1173         or
1174         <literal><parameter>non-string</parameter> <literal>||</literal>
1175         <parameter>string</parameter></literal>
1176        </entry>
1177        <entry> <type>text</type> </entry>
1178        <entry>
1179         String concatenation with one non-string input
1180        </entry>
1181        <entry><literal>'Value: ' || 42</literal></entry>
1182        <entry><literal>Value: 42</literal></entry>
1183       </row>
1184
1185       <row>
1186        <entry>
1187         <indexterm>
1188          <primary>bit_length</primary>
1189         </indexterm>
1190         <literal><function>bit_length(<parameter>string</parameter>)</function></literal>
1191        </entry>
1192        <entry><type>int</type></entry>
1193        <entry>Number of bits in string</entry>
1194        <entry><literal>bit_length('jose')</literal></entry>
1195        <entry><literal>32</literal></entry>
1196       </row>
1197
1198       <row>
1199        <entry>
1200         <indexterm>
1201          <primary>char_length</primary>
1202         </indexterm>
1203         <literal><function>char_length(<parameter>string</parameter>)</function></literal> or <literal><function>character_length(<parameter>string</parameter>)</function></literal>
1204        </entry>
1205        <entry><type>int</type></entry>
1206        <entry>
1207         Number of characters in string
1208         <indexterm>
1209          <primary>character string</primary>
1210          <secondary>length</secondary>
1211         </indexterm>
1212         <indexterm>
1213          <primary>length</primary>
1214          <secondary sortas="character string">of a character string</secondary>
1215          <see>character string, length</see>
1216         </indexterm>
1217        </entry>
1218        <entry><literal>char_length('jose')</literal></entry>
1219        <entry><literal>4</literal></entry>
1220       </row>
1221
1222       <row>
1223        <entry>
1224         <indexterm>
1225          <primary>lower</primary>
1226         </indexterm>
1227         <literal><function>lower(<parameter>string</parameter>)</function></literal>
1228        </entry>
1229        <entry><type>text</type></entry>
1230        <entry>Convert string to lower case</entry>
1231        <entry><literal>lower('TOM')</literal></entry>
1232        <entry><literal>tom</literal></entry>
1233       </row>
1234
1235       <row>
1236        <entry>
1237         <indexterm>
1238          <primary>octet_length</primary>
1239         </indexterm>
1240         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
1241        </entry>
1242        <entry><type>int</type></entry>
1243        <entry>Number of bytes in string</entry>
1244        <entry><literal>octet_length('jose')</literal></entry>
1245        <entry><literal>4</literal></entry>
1246       </row>
1247
1248       <row>
1249        <entry>
1250         <indexterm>
1251          <primary>overlay</primary>
1252         </indexterm>
1253         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
1254        </entry>
1255        <entry><type>text</type></entry>
1256        <entry>
1257         Replace substring
1258        </entry>
1259        <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
1260        <entry><literal>Thomas</literal></entry>
1261       </row>
1262
1263       <row>
1264        <entry>
1265         <indexterm>
1266          <primary>position</primary>
1267         </indexterm>
1268         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
1269        </entry>
1270        <entry><type>int</type></entry>
1271        <entry>Location of specified substring</entry>
1272        <entry><literal>position('om' in 'Thomas')</literal></entry>
1273        <entry><literal>3</literal></entry>
1274       </row>
1275
1276       <row>
1277        <entry>
1278         <indexterm>
1279          <primary>substring</primary>
1280         </indexterm>
1281         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
1282        </entry>
1283        <entry><type>text</type></entry>
1284        <entry>
1285         Extract substring
1286        </entry>
1287        <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
1288        <entry><literal>hom</literal></entry>
1289       </row>
1290
1291       <row>
1292        <entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</function></literal></entry>
1293        <entry><type>text</type></entry>
1294        <entry>
1295         Extract substring matching POSIX regular expression. See
1296         <xref linkend="functions-matching"> for more information on pattern
1297         matching.
1298        </entry>
1299        <entry><literal>substring('Thomas' from '...$')</literal></entry>
1300        <entry><literal>mas</literal></entry>
1301       </row>
1302
1303       <row>
1304        <entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</function></literal></entry>
1305        <entry><type>text</type></entry>
1306        <entry>
1307         Extract substring matching <acronym>SQL</acronym> regular expression.
1308         See <xref linkend="functions-matching"> for more information on
1309         pattern matching.
1310        </entry>
1311        <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
1312        <entry><literal>oma</literal></entry>
1313       </row>
1314
1315       <row>
1316        <entry>
1317         <indexterm>
1318          <primary>trim</primary>
1319         </indexterm>
1320         <literal><function>trim(<optional>leading | trailing | both</optional>
1321         <optional><parameter>characters</parameter></optional> from
1322         <parameter>string</parameter>)</function></literal>
1323        </entry>
1324        <entry><type>text</type></entry>
1325        <entry>
1326         Remove the longest string containing only the
1327         <parameter>characters</parameter> (a space by default) from the
1328         start/end/both ends of the <parameter>string</parameter>
1329        </entry>
1330        <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
1331        <entry><literal>Tom</literal></entry>
1332       </row>
1333
1334       <row>
1335        <entry>
1336         <literal><function>trim(<optional>leading | trailing
1337         | both</optional> <optional>from</optional>
1338         <parameter>string</parameter>
1339         <optional><parameter>, characters</parameter></optional>
1340         )</function></literal>
1341        </entry>
1342        <entry><type>text</type></entry>
1343        <entry>
1344         Non-standard version of <function>trim()</>
1345        </entry>
1346        <entry><literal>trim(both from 'xTomxx', 'x')</literal></entry>
1347        <entry><literal>Tom</literal></entry>
1348       </row>
1349
1350       <row>
1351        <entry>
1352         <indexterm>
1353          <primary>upper</primary>
1354         </indexterm>
1355         <literal><function>upper(<parameter>string</parameter>)</function></literal>
1356        </entry>
1357        <entry><type>text</type></entry>
1358        <entry>Convert string to upper case</entry>
1359        <entry><literal>upper('tom')</literal></entry>
1360        <entry><literal>TOM</literal></entry>
1361       </row>
1362      </tbody>
1363     </tgroup>
1364    </table>
1365
1366    <para>
1367     Additional string manipulation functions are available and are
1368     listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
1369     <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
1370    </para>
1371
1372    <table id="functions-string-other">
1373     <title>Other String Functions</title>
1374     <tgroup cols="5">
1375      <thead>
1376       <row>
1377        <entry>Function</entry>
1378        <entry>Return Type</entry>
1379        <entry>Description</entry>
1380        <entry>Example</entry>
1381        <entry>Result</entry>
1382       </row>
1383      </thead>
1384
1385      <tbody>
1386       <row>
1387        <entry>
1388         <indexterm>
1389          <primary>ascii</primary>
1390         </indexterm>
1391         <literal><function>ascii(<parameter>string</parameter>)</function></literal>
1392        </entry>
1393        <entry><type>int</type></entry>
1394        <entry>
1395         <acronym>ASCII</acronym> code of the first character of the
1396         argument.  For <acronym>UTF8</acronym> returns the Unicode code
1397         point of the character.  For other multibyte encodings, the
1398         argument must be an <acronym>ASCII</acronym> character.
1399        </entry>
1400        <entry><literal>ascii('x')</literal></entry>
1401        <entry><literal>120</literal></entry>
1402       </row>
1403
1404       <row>
1405        <entry>
1406         <indexterm>
1407          <primary>btrim</primary>
1408         </indexterm>
1409         <literal><function>btrim(<parameter>string</parameter> <type>text</type>
1410         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1411        </entry>
1412        <entry><type>text</type></entry>
1413        <entry>
1414         Remove the longest string consisting only of characters
1415         in <parameter>characters</parameter> (a space by default)
1416         from the start and end of <parameter>string</parameter>
1417        </entry>
1418        <entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
1419        <entry><literal>trim</literal></entry>
1420       </row>
1421
1422       <row>
1423        <entry>
1424         <indexterm>
1425          <primary>chr</primary>
1426         </indexterm>
1427         <literal><function>chr(<type>int</type>)</function></literal>
1428        </entry>
1429        <entry><type>text</type></entry>
1430        <entry>
1431         Character with the given code. For <acronym>UTF8</acronym> the
1432         argument is treated as a Unicode code point. For other multibyte
1433         encodings the argument must designate an
1434         <acronym>ASCII</acronym> character.  The NULL (0) character is not
1435         allowed because text data types cannot store such bytes.
1436        </entry>
1437        <entry><literal>chr(65)</literal></entry>
1438        <entry><literal>A</literal></entry>
1439       </row>
1440
1441       <row>
1442        <entry>
1443         <indexterm>
1444          <primary>concat</primary>
1445         </indexterm>
1446         <literal><function>concat(<parameter>str</parameter> <type>"any"</type>
1447          [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
1448        </entry>
1449        <entry><type>text</type></entry>
1450        <entry>
1451         Concatenate the text representations of all the arguments.
1452         NULL arguments are ignored.
1453        </entry>
1454        <entry><literal>concat('abcde', 2, NULL, 22)</literal></entry>
1455        <entry><literal>abcde222</literal></entry>
1456       </row>
1457
1458       <row>
1459        <entry>
1460         <indexterm>
1461          <primary>concat_ws</primary>
1462         </indexterm>
1463         <literal><function>concat_ws(<parameter>sep</parameter> <type>text</type>,
1464         <parameter>str</parameter> <type>"any"</type>
1465         [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
1466        </entry>
1467        <entry><type>text</type></entry>
1468        <entry>
1469         Concatenate all but the first argument with separators. The first
1470         argument is used as the separator string. NULL arguments are ignored.
1471        </entry>
1472        <entry><literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal></entry>
1473        <entry><literal>abcde,2,22</literal></entry>
1474       </row>
1475
1476       <row>
1477        <entry>
1478         <indexterm>
1479          <primary>convert</primary>
1480         </indexterm>
1481         <literal><function>convert(<parameter>string</parameter> <type>bytea</type>,
1482         <parameter>src_encoding</parameter> <type>name</type>,
1483         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1484        </entry>
1485        <entry><type>bytea</type></entry>
1486        <entry>
1487         Convert string to <parameter>dest_encoding</parameter>.  The
1488         original encoding is specified by
1489         <parameter>src_encoding</parameter>. The
1490         <parameter>string</parameter> must be valid in this encoding.
1491         Conversions can be defined by <command>CREATE CONVERSION</command>.
1492         Also there are some predefined conversions. See <xref
1493         linkend="conversion-names"> for available conversions.
1494        </entry>
1495        <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1496        <entry><literal>text_in_utf8</literal> represented in Latin-1
1497        encoding (ISO 8859-1)</entry>
1498       </row>
1499
1500       <row>
1501        <entry>
1502         <indexterm>
1503          <primary>convert_from</primary>
1504         </indexterm>
1505         <literal><function>convert_from(<parameter>string</parameter> <type>bytea</type>,
1506         <parameter>src_encoding</parameter> <type>name</type>)</function></literal>
1507        </entry>
1508        <entry><type>text</type></entry>
1509        <entry>
1510         Convert string to the database encoding.  The original encoding
1511         is specified by <parameter>src_encoding</parameter>. The
1512         <parameter>string</parameter> must be valid in this encoding.
1513        </entry>
1514        <entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
1515        <entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
1516       </row>
1517
1518       <row>
1519        <entry>
1520         <indexterm>
1521          <primary>convert_to</primary>
1522         </indexterm>
1523         <literal><function>convert_to(<parameter>string</parameter> <type>text</type>,
1524         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1525        </entry>
1526        <entry><type>bytea</type></entry>
1527        <entry>
1528         Convert string to <parameter>dest_encoding</parameter>.
1529        </entry>
1530        <entry><literal>convert_to('some text', 'UTF8')</literal></entry>
1531        <entry><literal>some text</literal> represented in the UTF8 encoding</entry>
1532       </row>
1533
1534       <row>
1535        <entry>
1536         <indexterm>
1537          <primary>decode</primary>
1538         </indexterm>
1539         <literal><function>decode(<parameter>string</parameter> <type>text</type>,
1540         <parameter>format</parameter> <type>text</type>)</function></literal>
1541        </entry>
1542        <entry><type>bytea</type></entry>
1543        <entry>
1544         Decode binary data from textual representation in <parameter>string</>.
1545         Options for <parameter>format</> are same as in <function>encode</>.
1546        </entry>
1547        <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
1548        <entry><literal>\x3132330001</literal></entry>
1549       </row>
1550
1551       <row>
1552        <entry>
1553         <indexterm>
1554          <primary>encode</primary>
1555         </indexterm>
1556         <literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
1557         <parameter>format</parameter> <type>text</type>)</function></literal>
1558        </entry>
1559        <entry><type>text</type></entry>
1560        <entry>
1561         Encode binary data into a textual representation.  Supported
1562         formats are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
1563         <literal>escape</> converts zero bytes and high-bit-set bytes to
1564         octal sequences (<literal>\</><replaceable>nnn</>) and
1565         doubles backslashes.
1566        </entry>
1567        <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1568        <entry><literal>MTIzAAE=</literal></entry>
1569       </row>
1570
1571       <row>
1572        <entry id="format">
1573         <indexterm>
1574          <primary>format</primary>
1575         </indexterm>
1576         <literal><function>format</function>(<parameter>formatstr</parameter> <type>text</type>
1577         [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ])</literal>
1578        </entry>
1579        <entry><type>text</type></entry>
1580        <entry>
1581          Format arguments according to a format string.
1582          This function is similar to the C function <function>sprintf</>.
1583          See <xref linkend="functions-string-format">.
1584        </entry>
1585        <entry><literal>format('Hello %s, %1$s', 'World')</literal></entry>
1586        <entry><literal>Hello World, World</literal></entry>
1587       </row>
1588
1589       <row>
1590        <entry>
1591         <indexterm>
1592          <primary>initcap</primary>
1593         </indexterm>
1594         <literal><function>initcap(<parameter>string</parameter>)</function></literal>
1595        </entry>
1596        <entry><type>text</type></entry>
1597        <entry>
1598         Convert the first letter of each word to upper case and the
1599         rest to lower case. Words are sequences of alphanumeric
1600         characters separated by non-alphanumeric characters.
1601        </entry>
1602        <entry><literal>initcap('hi THOMAS')</literal></entry>
1603        <entry><literal>Hi Thomas</literal></entry>
1604       </row>
1605
1606       <row>
1607        <entry>
1608         <indexterm>
1609          <primary>left</primary>
1610         </indexterm>
1611         <literal><function>left(<parameter>str</parameter> <type>text</type>,
1612         <parameter>n</parameter> <type>int</type>)</function></literal>
1613        </entry>
1614        <entry><type>text</type></entry>
1615        <entry>
1616         Return first <replaceable>n</> characters in the string. When <replaceable>n</>
1617         is negative, return all but last |<replaceable>n</>| characters.
1618         </entry>
1619        <entry><literal>left('abcde', 2)</literal></entry>
1620        <entry><literal>ab</literal></entry>
1621       </row>
1622
1623       <row>
1624        <entry>
1625         <indexterm>
1626          <primary>length</primary>
1627         </indexterm>
1628         <literal><function>length(<parameter>string</parameter>)</function></literal>
1629        </entry>
1630        <entry><type>int</type></entry>
1631        <entry>
1632         Number of characters in <parameter>string</parameter>
1633        </entry>
1634        <entry><literal>length('jose')</literal></entry>
1635        <entry><literal>4</literal></entry>
1636       </row>
1637
1638       <row>
1639        <entry><literal><function>length(<parameter>string</parameter> <type>bytea</type>,
1640         <parameter>encoding</parameter> <type>name</type> )</function></literal></entry>
1641        <entry><type>int</type></entry>
1642        <entry>
1643         Number of characters in <parameter>string</parameter> in the given
1644         <parameter>encoding</parameter>. The <parameter>string</parameter>
1645         must be valid in this encoding.
1646        </entry>
1647        <entry><literal>length('jose', 'UTF8')</literal></entry>
1648        <entry><literal>4</literal></entry>
1649       </row>
1650
1651       <row>
1652        <entry>
1653         <indexterm>
1654          <primary>lpad</primary>
1655         </indexterm>
1656         <literal><function>lpad(<parameter>string</parameter> <type>text</type>,
1657         <parameter>length</parameter> <type>int</type>
1658         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1659        </entry>
1660        <entry><type>text</type></entry>
1661        <entry>
1662         Fill up the <parameter>string</parameter> to length
1663         <parameter>length</parameter> by prepending the characters
1664         <parameter>fill</parameter> (a space by default).  If the
1665         <parameter>string</parameter> is already longer than
1666         <parameter>length</parameter> then it is truncated (on the
1667         right).
1668        </entry>
1669        <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1670        <entry><literal>xyxhi</literal></entry>
1671       </row>
1672
1673       <row>
1674        <entry>
1675         <indexterm>
1676          <primary>ltrim</primary>
1677         </indexterm>
1678         <literal><function>ltrim(<parameter>string</parameter> <type>text</type>
1679         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1680        </entry>
1681        <entry><type>text</type></entry>
1682        <entry>
1683         Remove the longest string containing only characters from
1684         <parameter>characters</parameter> (a space by default) from the start of
1685         <parameter>string</parameter>
1686        </entry>
1687        <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
1688        <entry><literal>trim</literal></entry>
1689       </row>
1690
1691       <row>
1692        <entry>
1693         <indexterm>
1694          <primary>md5</primary>
1695         </indexterm>
1696         <literal><function>md5(<parameter>string</parameter>)</function></literal>
1697        </entry>
1698        <entry><type>text</type></entry>
1699        <entry>
1700         Calculates the MD5 hash of <parameter>string</parameter>,
1701         returning the result in hexadecimal
1702        </entry>
1703        <entry><literal>md5('abc')</literal></entry>
1704        <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1705       </row>
1706
1707       <row>
1708        <entry>
1709         <indexterm>
1710          <primary>pg_client_encoding</primary>
1711         </indexterm>
1712         <literal><function>pg_client_encoding()</function></literal>
1713        </entry>
1714        <entry><type>name</type></entry>
1715        <entry>
1716         Current client encoding name
1717        </entry>
1718        <entry><literal>pg_client_encoding()</literal></entry>
1719        <entry><literal>SQL_ASCII</literal></entry>
1720       </row>
1721
1722       <row>
1723        <entry>
1724         <indexterm>
1725          <primary>quote_ident</primary>
1726         </indexterm>
1727         <literal><function>quote_ident(<parameter>string</parameter> <type>text</type>)</function></literal>
1728        </entry>
1729        <entry><type>text</type></entry>
1730        <entry>
1731         Return the given string suitably quoted to be used as an identifier
1732         in an <acronym>SQL</acronym> statement string.
1733         Quotes are added only if necessary (i.e., if the string contains
1734         non-identifier characters or would be case-folded).
1735         Embedded quotes are properly doubled.
1736         See also <xref linkend="plpgsql-quote-literal-example">.
1737        </entry>
1738        <entry><literal>quote_ident('Foo bar')</literal></entry>
1739        <entry><literal>"Foo bar"</literal></entry>
1740       </row>
1741
1742       <row>
1743        <entry>
1744         <indexterm>
1745          <primary>quote_literal</primary>
1746         </indexterm>
1747         <literal><function>quote_literal(<parameter>string</parameter> <type>text</type>)</function></literal>
1748        </entry>
1749        <entry><type>text</type></entry>
1750        <entry>
1751         Return the given string suitably quoted to be used as a string literal
1752         in an <acronym>SQL</acronym> statement string.
1753         Embedded single-quotes and backslashes are properly doubled.
1754         Note that <function>quote_literal</function> returns null on null
1755         input; if the argument might be null,
1756         <function>quote_nullable</function> is often more suitable.
1757         See also <xref linkend="plpgsql-quote-literal-example">.
1758        </entry>
1759        <entry><literal>quote_literal(E'O\'Reilly')</literal></entry>
1760        <entry><literal>'O''Reilly'</literal></entry>
1761       </row>
1762
1763       <row>
1764        <entry><literal><function>quote_literal(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1765        <entry><type>text</type></entry>
1766        <entry>
1767         Coerce the given value to text and then quote it as a literal.
1768         Embedded single-quotes and backslashes are properly doubled.
1769        </entry>
1770        <entry><literal>quote_literal(42.5)</literal></entry>
1771        <entry><literal>'42.5'</literal></entry>
1772       </row>
1773
1774       <row>
1775        <entry>
1776         <indexterm>
1777          <primary>quote_nullable</primary>
1778         </indexterm>
1779         <literal><function>quote_nullable(<parameter>string</parameter> <type>text</type>)</function></literal>
1780        </entry>
1781        <entry><type>text</type></entry>
1782        <entry>
1783         Return the given string suitably quoted to be used as a string literal
1784         in an <acronym>SQL</acronym> statement string; or, if the argument
1785         is null, return <literal>NULL</>.
1786         Embedded single-quotes and backslashes are properly doubled.
1787         See also <xref linkend="plpgsql-quote-literal-example">.
1788        </entry>
1789        <entry><literal>quote_nullable(NULL)</literal></entry>
1790        <entry><literal>NULL</literal></entry>
1791       </row>
1792
1793       <row>
1794        <entry><literal><function>quote_nullable(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1795        <entry><type>text</type></entry>
1796        <entry>
1797         Coerce the given value to text and then quote it as a literal;
1798         or, if the argument is null, return <literal>NULL</>.
1799         Embedded single-quotes and backslashes are properly doubled.
1800        </entry>
1801        <entry><literal>quote_nullable(42.5)</literal></entry>
1802        <entry><literal>'42.5'</literal></entry>
1803       </row>
1804
1805       <row>
1806        <entry>
1807         <indexterm>
1808          <primary>regexp_matches</primary>
1809         </indexterm>
1810         <literal><function>regexp_matches(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
1811        </entry>
1812        <entry><type>setof text[]</type></entry>
1813        <entry>
1814         Return all captured substrings resulting from matching a POSIX regular
1815         expression against the <parameter>string</parameter>. See
1816         <xref linkend="functions-posix-regexp"> for more information.
1817        </entry>
1818        <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
1819        <entry><literal>{bar,beque}</literal></entry>
1820       </row>
1821
1822       <row>
1823        <entry>
1824         <indexterm>
1825          <primary>regexp_replace</primary>
1826         </indexterm>
1827         <literal><function>regexp_replace(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
1828        </entry>
1829        <entry><type>text</type></entry>
1830        <entry>
1831         Replace substring(s) matching a POSIX regular expression. See
1832         <xref linkend="functions-posix-regexp"> for more information.
1833        </entry>
1834        <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
1835        <entry><literal>ThM</literal></entry>
1836       </row>
1837
1838       <row>
1839        <entry>
1840         <indexterm>
1841          <primary>regexp_split_to_array</primary>
1842         </indexterm>
1843         <literal><function>regexp_split_to_array(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ])</function></literal>
1844        </entry>
1845        <entry><type>text[]</type></entry>
1846        <entry>
1847         Split <parameter>string</parameter> using a POSIX regular expression as
1848         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1849         information.
1850        </entry>
1851        <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
1852        <entry><literal>{hello,world}</literal></entry>
1853       </row>
1854
1855       <row>
1856        <entry>
1857         <indexterm>
1858          <primary>regexp_split_to_table</primary>
1859         </indexterm>
1860         <literal><function>regexp_split_to_table(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
1861        </entry>
1862        <entry><type>setof text</type></entry>
1863        <entry>
1864         Split <parameter>string</parameter> using a POSIX regular expression as
1865         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1866         information.
1867        </entry>
1868        <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
1869        <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
1870       </row>
1871
1872       <row>
1873        <entry>
1874         <indexterm>
1875          <primary>repeat</primary>
1876         </indexterm>
1877         <literal><function>repeat(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</function></literal>
1878        </entry>
1879        <entry><type>text</type></entry>
1880        <entry>Repeat <parameter>string</parameter> the specified
1881        <parameter>number</parameter> of times</entry>
1882        <entry><literal>repeat('Pg', 4)</literal></entry>
1883        <entry><literal>PgPgPgPg</literal></entry>
1884       </row>
1885
1886       <row>
1887        <entry>
1888         <indexterm>
1889          <primary>replace</primary>
1890         </indexterm>
1891         <literal><function>replace(<parameter>string</parameter> <type>text</type>,
1892         <parameter>from</parameter> <type>text</type>,
1893         <parameter>to</parameter> <type>text</type>)</function></literal>
1894        </entry>
1895        <entry><type>text</type></entry>
1896        <entry>Replace all occurrences in <parameter>string</parameter> of substring
1897         <parameter>from</parameter> with substring <parameter>to</parameter>
1898        </entry>
1899        <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
1900        <entry><literal>abXXefabXXef</literal></entry>
1901       </row>
1902
1903       <row>
1904        <entry>
1905         <indexterm>
1906          <primary>reverse</primary>
1907         </indexterm>
1908         <literal><function>reverse(<parameter>str</parameter>)</function></literal>
1909        </entry>
1910        <entry><type>text</type></entry>
1911        <entry>
1912         Return reversed string.
1913        </entry>
1914        <entry><literal>reverse('abcde')</literal></entry>
1915        <entry><literal>edcba</literal></entry>
1916       </row>
1917
1918       <row>
1919        <entry>
1920         <indexterm>
1921          <primary>right</primary>
1922         </indexterm>
1923         <literal><function>right(<parameter>str</parameter> <type>text</type>,
1924          <parameter>n</parameter> <type>int</type>)</function></literal>
1925        </entry>
1926        <entry><type>text</type></entry>
1927        <entry>
1928         Return last <replaceable>n</> characters in the string. When <replaceable>n</>
1929         is negative, return all but first |<replaceable>n</>| characters.
1930        </entry>
1931        <entry><literal>right('abcde', 2)</literal></entry>
1932        <entry><literal>de</literal></entry>
1933       </row>
1934
1935       <row>
1936        <entry>
1937         <indexterm>
1938          <primary>rpad</primary>
1939         </indexterm>
1940         <literal><function>rpad(<parameter>string</parameter> <type>text</type>,
1941         <parameter>length</parameter> <type>int</type>
1942         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1943        </entry>
1944        <entry><type>text</type></entry>
1945        <entry>
1946         Fill up the <parameter>string</parameter> to length
1947         <parameter>length</parameter> by appending the characters
1948         <parameter>fill</parameter> (a space by default).  If the
1949         <parameter>string</parameter> is already longer than
1950         <parameter>length</parameter> then it is truncated.
1951        </entry>
1952        <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
1953        <entry><literal>hixyx</literal></entry>
1954       </row>
1955
1956       <row>
1957        <entry>
1958         <indexterm>
1959          <primary>rtrim</primary>
1960         </indexterm>
1961         <literal><function>rtrim(<parameter>string</parameter> <type>text</type>
1962          <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1963        </entry>
1964        <entry><type>text</type></entry>
1965        <entry>
1966         Remove the longest string containing only characters from
1967         <parameter>characters</parameter> (a space by default) from the end of
1968         <parameter>string</parameter>
1969        </entry>
1970        <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
1971        <entry><literal>trim</literal></entry>
1972       </row>
1973
1974       <row>
1975        <entry>
1976         <indexterm>
1977          <primary>split_part</primary>
1978         </indexterm>
1979         <literal><function>split_part(<parameter>string</parameter> <type>text</type>,
1980         <parameter>delimiter</parameter> <type>text</type>,
1981         <parameter>field</parameter> <type>int</type>)</function></literal>
1982        </entry>
1983        <entry><type>text</type></entry>
1984        <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1985         and return the given field (counting from one)
1986        </entry>
1987        <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
1988        <entry><literal>def</literal></entry>
1989       </row>
1990
1991       <row>
1992        <entry>
1993         <indexterm>
1994          <primary>strpos</primary>
1995         </indexterm>
1996         <literal><function>strpos(<parameter>string</parameter>, <parameter>substring</parameter>)</function></literal>
1997        </entry>
1998        <entry><type>int</type></entry>
1999        <entry>
2000         Location of specified substring (same as
2001         <literal>position(<parameter>substring</parameter> in
2002          <parameter>string</parameter>)</literal>, but note the reversed
2003         argument order)
2004        </entry>
2005        <entry><literal>strpos('high', 'ig')</literal></entry>
2006        <entry><literal>2</literal></entry>
2007       </row>
2008
2009       <row>
2010        <entry>
2011         <indexterm>
2012          <primary>substr</primary>
2013         </indexterm>
2014         <literal><function>substr(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</function></literal>
2015        </entry>
2016        <entry><type>text</type></entry>
2017        <entry>
2018         Extract substring (same as
2019         <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
2020        </entry>
2021        <entry><literal>substr('alphabet', 3, 2)</literal></entry>
2022        <entry><literal>ph</literal></entry>
2023       </row>
2024
2025       <row>
2026        <entry>
2027         <indexterm>
2028          <primary>to_ascii</primary>
2029         </indexterm>
2030         <literal><function>to_ascii(<parameter>string</parameter> <type>text</type>
2031         <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</function></literal>
2032        </entry>
2033        <entry><type>text</type></entry>
2034        <entry>
2035        Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
2036        (only supports conversion from  <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
2037        and <literal>WIN1250</> encodings)
2038        </entry>
2039        <entry><literal>to_ascii('Karel')</literal></entry>
2040        <entry><literal>Karel</literal></entry>
2041       </row>
2042
2043       <row>
2044        <entry>
2045         <indexterm>
2046          <primary>to_hex</primary>
2047         </indexterm>
2048         <literal><function>to_hex(<parameter>number</parameter> <type>int</type>
2049         or <type>bigint</type>)</function></literal>
2050        </entry>
2051        <entry><type>text</type></entry>
2052        <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
2053         representation
2054        </entry>
2055        <entry><literal>to_hex(2147483647)</literal></entry>
2056        <entry><literal>7fffffff</literal></entry>
2057       </row>
2058
2059       <row>
2060        <entry>
2061         <indexterm>
2062          <primary>translate</primary>
2063         </indexterm>
2064         <literal><function>translate(<parameter>string</parameter> <type>text</type>,
2065         <parameter>from</parameter> <type>text</type>,
2066         <parameter>to</parameter> <type>text</type>)</function></literal>
2067        </entry>
2068        <entry><type>text</type></entry>
2069        <entry>
2070         Any character in <parameter>string</parameter> that matches a
2071         character in the <parameter>from</parameter> set is replaced by
2072         the corresponding character in the <parameter>to</parameter>
2073         set. If <parameter>from</parameter> is longer than
2074         <parameter>to</parameter>, occurrences of the extra characters in
2075         <parameter>from</parameter> are removed.
2076        </entry>
2077        <entry><literal>translate('12345', '143', 'ax')</literal></entry>
2078        <entry><literal>a2x5</literal></entry>
2079       </row>
2080
2081      </tbody>
2082     </tgroup>
2083    </table>
2084
2085    <para>
2086     The <function>concat</function>, <function>concat_ws</function> and
2087     <function>format</function> functions are variadic, so it is possible to
2088     pass the values to be concatenated or formatted as an array marked with
2089     the <literal>VARIADIC</literal> keyword (see <xref
2090     linkend="xfunc-sql-variadic-functions">).  The array's elements are
2091     treated as if they were separate ordinary arguments to the function.
2092     If the variadic array argument is NULL, <function>concat</function>
2093     and <function>concat_ws</function> return NULL, but
2094     <function>format</function> treats a NULL as a zero-element array.
2095    </para>
2096
2097    <para>
2098    See also the aggregate function <function>string_agg</function> in
2099    <xref linkend="functions-aggregate">.
2100    </para>
2101
2102    <table id="conversion-names">
2103     <title>Built-in Conversions</title>
2104     <tgroup cols="3">
2105      <thead>
2106       <row>
2107        <entry>Conversion Name
2108         <footnote>
2109          <para>
2110           The conversion names follow a standard naming scheme: The
2111           official name of the source encoding with all
2112           non-alphanumeric characters replaced by underscores, followed
2113           by <literal>_to_</literal>, followed by the similarly processed
2114           destination encoding name. Therefore, the names might deviate
2115           from the customary encoding names.
2116          </para>
2117         </footnote>
2118        </entry>
2119        <entry>Source Encoding</entry>
2120        <entry>Destination Encoding</entry>
2121       </row>
2122      </thead>
2123
2124      <tbody>
2125       <row>
2126        <entry><literal>ascii_to_mic</literal></entry>
2127        <entry><literal>SQL_ASCII</literal></entry>
2128        <entry><literal>MULE_INTERNAL</literal></entry>
2129       </row>
2130
2131       <row>
2132        <entry><literal>ascii_to_utf8</literal></entry>
2133        <entry><literal>SQL_ASCII</literal></entry>
2134        <entry><literal>UTF8</literal></entry>
2135       </row>
2136
2137       <row>
2138        <entry><literal>big5_to_euc_tw</literal></entry>
2139        <entry><literal>BIG5</literal></entry>
2140        <entry><literal>EUC_TW</literal></entry>
2141       </row>
2142
2143       <row>
2144        <entry><literal>big5_to_mic</literal></entry>
2145        <entry><literal>BIG5</literal></entry>
2146        <entry><literal>MULE_INTERNAL</literal></entry>
2147       </row>
2148
2149       <row>
2150        <entry><literal>big5_to_utf8</literal></entry>
2151        <entry><literal>BIG5</literal></entry>
2152        <entry><literal>UTF8</literal></entry>
2153       </row>
2154
2155       <row>
2156        <entry><literal>euc_cn_to_mic</literal></entry>
2157        <entry><literal>EUC_CN</literal></entry>
2158        <entry><literal>MULE_INTERNAL</literal></entry>
2159       </row>
2160
2161       <row>
2162        <entry><literal>euc_cn_to_utf8</literal></entry>
2163        <entry><literal>EUC_CN</literal></entry>
2164        <entry><literal>UTF8</literal></entry>
2165       </row>
2166
2167       <row>
2168        <entry><literal>euc_jp_to_mic</literal></entry>
2169        <entry><literal>EUC_JP</literal></entry>
2170        <entry><literal>MULE_INTERNAL</literal></entry>
2171       </row>
2172
2173       <row>
2174        <entry><literal>euc_jp_to_sjis</literal></entry>
2175        <entry><literal>EUC_JP</literal></entry>
2176        <entry><literal>SJIS</literal></entry>
2177       </row>
2178
2179       <row>
2180        <entry><literal>euc_jp_to_utf8</literal></entry>
2181        <entry><literal>EUC_JP</literal></entry>
2182        <entry><literal>UTF8</literal></entry>
2183       </row>
2184
2185       <row>
2186        <entry><literal>euc_kr_to_mic</literal></entry>
2187        <entry><literal>EUC_KR</literal></entry>
2188        <entry><literal>MULE_INTERNAL</literal></entry>
2189       </row>
2190
2191       <row>
2192        <entry><literal>euc_kr_to_utf8</literal></entry>
2193        <entry><literal>EUC_KR</literal></entry>
2194        <entry><literal>UTF8</literal></entry>
2195       </row>
2196
2197       <row>
2198        <entry><literal>euc_tw_to_big5</literal></entry>
2199        <entry><literal>EUC_TW</literal></entry>
2200        <entry><literal>BIG5</literal></entry>
2201       </row>
2202
2203       <row>
2204        <entry><literal>euc_tw_to_mic</literal></entry>
2205        <entry><literal>EUC_TW</literal></entry>
2206        <entry><literal>MULE_INTERNAL</literal></entry>
2207       </row>
2208
2209       <row>
2210        <entry><literal>euc_tw_to_utf8</literal></entry>
2211        <entry><literal>EUC_TW</literal></entry>
2212        <entry><literal>UTF8</literal></entry>
2213       </row>
2214
2215       <row>
2216        <entry><literal>gb18030_to_utf8</literal></entry>
2217        <entry><literal>GB18030</literal></entry>
2218        <entry><literal>UTF8</literal></entry>
2219       </row>
2220
2221       <row>
2222        <entry><literal>gbk_to_utf8</literal></entry>
2223        <entry><literal>GBK</literal></entry>
2224        <entry><literal>UTF8</literal></entry>
2225       </row>
2226
2227       <row>
2228        <entry><literal>iso_8859_10_to_utf8</literal></entry>
2229        <entry><literal>LATIN6</literal></entry>
2230        <entry><literal>UTF8</literal></entry>
2231       </row>
2232
2233       <row>
2234        <entry><literal>iso_8859_13_to_utf8</literal></entry>
2235        <entry><literal>LATIN7</literal></entry>
2236        <entry><literal>UTF8</literal></entry>
2237       </row>
2238
2239       <row>
2240        <entry><literal>iso_8859_14_to_utf8</literal></entry>
2241        <entry><literal>LATIN8</literal></entry>
2242        <entry><literal>UTF8</literal></entry>
2243       </row>
2244
2245       <row>
2246        <entry><literal>iso_8859_15_to_utf8</literal></entry>
2247        <entry><literal>LATIN9</literal></entry>
2248        <entry><literal>UTF8</literal></entry>
2249       </row>
2250
2251       <row>
2252        <entry><literal>iso_8859_16_to_utf8</literal></entry>
2253        <entry><literal>LATIN10</literal></entry>
2254        <entry><literal>UTF8</literal></entry>
2255       </row>
2256
2257       <row>
2258        <entry><literal>iso_8859_1_to_mic</literal></entry>
2259        <entry><literal>LATIN1</literal></entry>
2260        <entry><literal>MULE_INTERNAL</literal></entry>
2261       </row>
2262
2263       <row>
2264        <entry><literal>iso_8859_1_to_utf8</literal></entry>
2265        <entry><literal>LATIN1</literal></entry>
2266        <entry><literal>UTF8</literal></entry>
2267       </row>
2268
2269       <row>
2270        <entry><literal>iso_8859_2_to_mic</literal></entry>
2271        <entry><literal>LATIN2</literal></entry>
2272        <entry><literal>MULE_INTERNAL</literal></entry>
2273       </row>
2274
2275       <row>
2276        <entry><literal>iso_8859_2_to_utf8</literal></entry>
2277        <entry><literal>LATIN2</literal></entry>
2278        <entry><literal>UTF8</literal></entry>
2279       </row>
2280
2281       <row>
2282        <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
2283        <entry><literal>LATIN2</literal></entry>
2284        <entry><literal>WIN1250</literal></entry>
2285       </row>
2286
2287       <row>
2288        <entry><literal>iso_8859_3_to_mic</literal></entry>
2289        <entry><literal>LATIN3</literal></entry>
2290        <entry><literal>MULE_INTERNAL</literal></entry>
2291       </row>
2292
2293       <row>
2294        <entry><literal>iso_8859_3_to_utf8</literal></entry>
2295        <entry><literal>LATIN3</literal></entry>
2296        <entry><literal>UTF8</literal></entry>
2297       </row>
2298
2299       <row>
2300        <entry><literal>iso_8859_4_to_mic</literal></entry>
2301        <entry><literal>LATIN4</literal></entry>
2302        <entry><literal>MULE_INTERNAL</literal></entry>
2303       </row>
2304
2305       <row>
2306        <entry><literal>iso_8859_4_to_utf8</literal></entry>
2307        <entry><literal>LATIN4</literal></entry>
2308        <entry><literal>UTF8</literal></entry>
2309       </row>
2310
2311       <row>
2312        <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
2313        <entry><literal>ISO_8859_5</literal></entry>
2314        <entry><literal>KOI8R</literal></entry>
2315       </row>
2316
2317       <row>
2318        <entry><literal>iso_8859_5_to_mic</literal></entry>
2319        <entry><literal>ISO_8859_5</literal></entry>
2320        <entry><literal>MULE_INTERNAL</literal></entry>
2321       </row>
2322
2323       <row>
2324        <entry><literal>iso_8859_5_to_utf8</literal></entry>
2325        <entry><literal>ISO_8859_5</literal></entry>
2326        <entry><literal>UTF8</literal></entry>
2327       </row>
2328
2329       <row>
2330        <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
2331        <entry><literal>ISO_8859_5</literal></entry>
2332        <entry><literal>WIN1251</literal></entry>
2333       </row>
2334
2335       <row>
2336        <entry><literal>iso_8859_5_to_windows_866</literal></entry>
2337        <entry><literal>ISO_8859_5</literal></entry>
2338        <entry><literal>WIN866</literal></entry>
2339       </row>
2340
2341       <row>
2342        <entry><literal>iso_8859_6_to_utf8</literal></entry>
2343        <entry><literal>ISO_8859_6</literal></entry>
2344        <entry><literal>UTF8</literal></entry>
2345       </row>
2346
2347       <row>
2348        <entry><literal>iso_8859_7_to_utf8</literal></entry>
2349        <entry><literal>ISO_8859_7</literal></entry>
2350        <entry><literal>UTF8</literal></entry>
2351       </row>
2352
2353       <row>
2354        <entry><literal>iso_8859_8_to_utf8</literal></entry>
2355        <entry><literal>ISO_8859_8</literal></entry>
2356        <entry><literal>UTF8</literal></entry>
2357       </row>
2358
2359       <row>
2360        <entry><literal>iso_8859_9_to_utf8</literal></entry>
2361        <entry><literal>LATIN5</literal></entry>
2362        <entry><literal>UTF8</literal></entry>
2363       </row>
2364
2365       <row>
2366        <entry><literal>johab_to_utf8</literal></entry>
2367        <entry><literal>JOHAB</literal></entry>
2368        <entry><literal>UTF8</literal></entry>
2369       </row>
2370
2371       <row>
2372        <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
2373        <entry><literal>KOI8R</literal></entry>
2374        <entry><literal>ISO_8859_5</literal></entry>
2375       </row>
2376
2377       <row>
2378        <entry><literal>koi8_r_to_mic</literal></entry>
2379        <entry><literal>KOI8R</literal></entry>
2380        <entry><literal>MULE_INTERNAL</literal></entry>
2381       </row>
2382
2383       <row>
2384        <entry><literal>koi8_r_to_utf8</literal></entry>
2385        <entry><literal>KOI8R</literal></entry>
2386        <entry><literal>UTF8</literal></entry>
2387       </row>
2388
2389       <row>
2390        <entry><literal>koi8_r_to_windows_1251</literal></entry>
2391        <entry><literal>KOI8R</literal></entry>
2392        <entry><literal>WIN1251</literal></entry>
2393       </row>
2394
2395       <row>
2396        <entry><literal>koi8_r_to_windows_866</literal></entry>
2397        <entry><literal>KOI8R</literal></entry>
2398        <entry><literal>WIN866</literal></entry>
2399       </row>
2400
2401       <row>
2402        <entry><literal>koi8_u_to_utf8</literal></entry>
2403        <entry><literal>KOI8U</literal></entry>
2404        <entry><literal>UTF8</literal></entry>
2405       </row>
2406
2407       <row>
2408        <entry><literal>mic_to_ascii</literal></entry>
2409        <entry><literal>MULE_INTERNAL</literal></entry>
2410        <entry><literal>SQL_ASCII</literal></entry>
2411       </row>
2412
2413       <row>
2414        <entry><literal>mic_to_big5</literal></entry>
2415        <entry><literal>MULE_INTERNAL</literal></entry>
2416        <entry><literal>BIG5</literal></entry>
2417       </row>
2418
2419       <row>
2420        <entry><literal>mic_to_euc_cn</literal></entry>
2421        <entry><literal>MULE_INTERNAL</literal></entry>
2422        <entry><literal>EUC_CN</literal></entry>
2423       </row>
2424
2425       <row>
2426        <entry><literal>mic_to_euc_jp</literal></entry>
2427        <entry><literal>MULE_INTERNAL</literal></entry>
2428        <entry><literal>EUC_JP</literal></entry>
2429       </row>
2430
2431       <row>
2432        <entry><literal>mic_to_euc_kr</literal></entry>
2433        <entry><literal>MULE_INTERNAL</literal></entry>
2434        <entry><literal>EUC_KR</literal></entry>
2435       </row>
2436
2437       <row>
2438        <entry><literal>mic_to_euc_tw</literal></entry>
2439        <entry><literal>MULE_INTERNAL</literal></entry>
2440        <entry><literal>EUC_TW</literal></entry>
2441       </row>
2442
2443       <row>
2444        <entry><literal>mic_to_iso_8859_1</literal></entry>
2445        <entry><literal>MULE_INTERNAL</literal></entry>
2446        <entry><literal>LATIN1</literal></entry>
2447       </row>
2448
2449       <row>
2450        <entry><literal>mic_to_iso_8859_2</literal></entry>
2451        <entry><literal>MULE_INTERNAL</literal></entry>
2452        <entry><literal>LATIN2</literal></entry>
2453       </row>
2454
2455       <row>
2456        <entry><literal>mic_to_iso_8859_3</literal></entry>
2457        <entry><literal>MULE_INTERNAL</literal></entry>
2458        <entry><literal>LATIN3</literal></entry>
2459       </row>
2460
2461       <row>
2462        <entry><literal>mic_to_iso_8859_4</literal></entry>
2463        <entry><literal>MULE_INTERNAL</literal></entry>
2464        <entry><literal>LATIN4</literal></entry>
2465       </row>
2466
2467       <row>
2468        <entry><literal>mic_to_iso_8859_5</literal></entry>
2469        <entry><literal>MULE_INTERNAL</literal></entry>
2470        <entry><literal>ISO_8859_5</literal></entry>
2471       </row>
2472
2473       <row>
2474        <entry><literal>mic_to_koi8_r</literal></entry>
2475        <entry><literal>MULE_INTERNAL</literal></entry>
2476        <entry><literal>KOI8R</literal></entry>
2477       </row>
2478
2479       <row>
2480        <entry><literal>mic_to_sjis</literal></entry>
2481        <entry><literal>MULE_INTERNAL</literal></entry>
2482        <entry><literal>SJIS</literal></entry>
2483       </row>
2484
2485       <row>
2486        <entry><literal>mic_to_windows_1250</literal></entry>
2487        <entry><literal>MULE_INTERNAL</literal></entry>
2488        <entry><literal>WIN1250</literal></entry>
2489       </row>
2490
2491       <row>
2492        <entry><literal>mic_to_windows_1251</literal></entry>
2493        <entry><literal>MULE_INTERNAL</literal></entry>
2494        <entry><literal>WIN1251</literal></entry>
2495       </row>
2496
2497       <row>
2498        <entry><literal>mic_to_windows_866</literal></entry>
2499        <entry><literal>MULE_INTERNAL</literal></entry>
2500        <entry><literal>WIN866</literal></entry>
2501       </row>
2502
2503       <row>
2504        <entry><literal>sjis_to_euc_jp</literal></entry>
2505        <entry><literal>SJIS</literal></entry>
2506        <entry><literal>EUC_JP</literal></entry>
2507       </row>
2508
2509       <row>
2510        <entry><literal>sjis_to_mic</literal></entry>
2511        <entry><literal>SJIS</literal></entry>
2512        <entry><literal>MULE_INTERNAL</literal></entry>
2513       </row>
2514
2515       <row>
2516        <entry><literal>sjis_to_utf8</literal></entry>
2517        <entry><literal>SJIS</literal></entry>
2518        <entry><literal>UTF8</literal></entry>
2519       </row>
2520
2521       <row>
2522        <entry><literal>tcvn_to_utf8</literal></entry>
2523        <entry><literal>WIN1258</literal></entry>
2524        <entry><literal>UTF8</literal></entry>
2525       </row>
2526
2527       <row>
2528        <entry><literal>uhc_to_utf8</literal></entry>
2529        <entry><literal>UHC</literal></entry>
2530        <entry><literal>UTF8</literal></entry>
2531       </row>
2532
2533       <row>
2534        <entry><literal>utf8_to_ascii</literal></entry>
2535        <entry><literal>UTF8</literal></entry>
2536        <entry><literal>SQL_ASCII</literal></entry>
2537       </row>
2538
2539       <row>
2540        <entry><literal>utf8_to_big5</literal></entry>
2541        <entry><literal>UTF8</literal></entry>
2542        <entry><literal>BIG5</literal></entry>
2543       </row>
2544
2545       <row>
2546        <entry><literal>utf8_to_euc_cn</literal></entry>
2547        <entry><literal>UTF8</literal></entry>
2548        <entry><literal>EUC_CN</literal></entry>
2549       </row>
2550
2551       <row>
2552        <entry><literal>utf8_to_euc_jp</literal></entry>
2553        <entry><literal>UTF8</literal></entry>
2554        <entry><literal>EUC_JP</literal></entry>
2555       </row>
2556
2557       <row>
2558        <entry><literal>utf8_to_euc_kr</literal></entry>
2559        <entry><literal>UTF8</literal></entry>
2560        <entry><literal>EUC_KR</literal></entry>
2561       </row>
2562
2563       <row>
2564        <entry><literal>utf8_to_euc_tw</literal></entry>
2565        <entry><literal>UTF8</literal></entry>
2566        <entry><literal>EUC_TW</literal></entry>
2567       </row>
2568
2569       <row>
2570        <entry><literal>utf8_to_gb18030</literal></entry>
2571        <entry><literal>UTF8</literal></entry>
2572        <entry><literal>GB18030</literal></entry>
2573       </row>
2574
2575       <row>
2576        <entry><literal>utf8_to_gbk</literal></entry>
2577        <entry><literal>UTF8</literal></entry>
2578        <entry><literal>GBK</literal></entry>
2579       </row>
2580
2581       <row>
2582        <entry><literal>utf8_to_iso_8859_1</literal></entry>
2583        <entry><literal>UTF8</literal></entry>
2584        <entry><literal>LATIN1</literal></entry>
2585       </row>
2586
2587       <row>
2588        <entry><literal>utf8_to_iso_8859_10</literal></entry>
2589        <entry><literal>UTF8</literal></entry>
2590        <entry><literal>LATIN6</literal></entry>
2591       </row>
2592
2593       <row>
2594        <entry><literal>utf8_to_iso_8859_13</literal></entry>
2595        <entry><literal>UTF8</literal></entry>
2596        <entry><literal>LATIN7</literal></entry>
2597       </row>
2598
2599       <row>
2600        <entry><literal>utf8_to_iso_8859_14</literal></entry>
2601        <entry><literal>UTF8</literal></entry>
2602        <entry><literal>LATIN8</literal></entry>
2603       </row>
2604
2605       <row>
2606        <entry><literal>utf8_to_iso_8859_15</literal></entry>
2607        <entry><literal>UTF8</literal></entry>
2608        <entry><literal>LATIN9</literal></entry>
2609       </row>
2610
2611       <row>
2612        <entry><literal>utf8_to_iso_8859_16</literal></entry>
2613        <entry><literal>UTF8</literal></entry>
2614        <entry><literal>LATIN10</literal></entry>
2615       </row>
2616
2617       <row>
2618        <entry><literal>utf8_to_iso_8859_2</literal></entry>
2619        <entry><literal>UTF8</literal></entry>
2620        <entry><literal>LATIN2</literal></entry>
2621       </row>
2622
2623       <row>
2624        <entry><literal>utf8_to_iso_8859_3</literal></entry>
2625        <entry><literal>UTF8</literal></entry>
2626        <entry><literal>LATIN3</literal></entry>
2627       </row>
2628
2629       <row>
2630        <entry><literal>utf8_to_iso_8859_4</literal></entry>
2631        <entry><literal>UTF8</literal></entry>
2632        <entry><literal>LATIN4</literal></entry>
2633       </row>
2634
2635       <row>
2636        <entry><literal>utf8_to_iso_8859_5</literal></entry>
2637        <entry><literal>UTF8</literal></entry>
2638        <entry><literal>ISO_8859_5</literal></entry>
2639       </row>
2640
2641       <row>
2642        <entry><literal>utf8_to_iso_8859_6</literal></entry>
2643        <entry><literal>UTF8</literal></entry>
2644        <entry><literal>ISO_8859_6</literal></entry>
2645       </row>
2646
2647       <row>
2648        <entry><literal>utf8_to_iso_8859_7</literal></entry>
2649        <entry><literal>UTF8</literal></entry>
2650        <entry><literal>ISO_8859_7</literal></entry>
2651       </row>
2652
2653       <row>
2654        <entry><literal>utf8_to_iso_8859_8</literal></entry>
2655        <entry><literal>UTF8</literal></entry>
2656        <entry><literal>ISO_8859_8</literal></entry>
2657       </row>
2658
2659       <row>
2660        <entry><literal>utf8_to_iso_8859_9</literal></entry>
2661        <entry><literal>UTF8</literal></entry>
2662        <entry><literal>LATIN5</literal></entry>
2663       </row>
2664
2665       <row>
2666        <entry><literal>utf8_to_johab</literal></entry>
2667        <entry><literal>UTF8</literal></entry>
2668        <entry><literal>JOHAB</literal></entry>
2669       </row>
2670
2671       <row>
2672        <entry><literal>utf8_to_koi8_r</literal></entry>
2673        <entry><literal>UTF8</literal></entry>
2674        <entry><literal>KOI8R</literal></entry>
2675       </row>
2676
2677       <row>
2678        <entry><literal>utf8_to_koi8_u</literal></entry>
2679        <entry><literal>UTF8</literal></entry>
2680        <entry><literal>KOI8U</literal></entry>
2681       </row>
2682
2683       <row>
2684        <entry><literal>utf8_to_sjis</literal></entry>
2685        <entry><literal>UTF8</literal></entry>
2686        <entry><literal>SJIS</literal></entry>
2687       </row>
2688
2689       <row>
2690        <entry><literal>utf8_to_tcvn</literal></entry>
2691        <entry><literal>UTF8</literal></entry>
2692        <entry><literal>WIN1258</literal></entry>
2693       </row>
2694
2695       <row>
2696        <entry><literal>utf8_to_uhc</literal></entry>
2697        <entry><literal>UTF8</literal></entry>
2698        <entry><literal>UHC</literal></entry>
2699       </row>
2700
2701       <row>
2702        <entry><literal>utf8_to_windows_1250</literal></entry>
2703        <entry><literal>UTF8</literal></entry>
2704        <entry><literal>WIN1250</literal></entry>
2705       </row>
2706
2707       <row>
2708        <entry><literal>utf8_to_windows_1251</literal></entry>
2709        <entry><literal>UTF8</literal></entry>
2710        <entry><literal>WIN1251</literal></entry>
2711       </row>
2712
2713       <row>
2714        <entry><literal>utf8_to_windows_1252</literal></entry>
2715        <entry><literal>UTF8</literal></entry>
2716        <entry><literal>WIN1252</literal></entry>
2717       </row>
2718
2719       <row>
2720        <entry><literal>utf8_to_windows_1253</literal></entry>
2721        <entry><literal>UTF8</literal></entry>
2722        <entry><literal>WIN1253</literal></entry>
2723       </row>
2724
2725       <row>
2726        <entry><literal>utf8_to_windows_1254</literal></entry>
2727        <entry><literal>UTF8</literal></entry>
2728        <entry><literal>WIN1254</literal></entry>
2729       </row>
2730
2731       <row>
2732        <entry><literal>utf8_to_windows_1255</literal></entry>
2733        <entry><literal>UTF8</literal></entry>
2734        <entry><literal>WIN1255</literal></entry>
2735       </row>
2736
2737       <row>
2738        <entry><literal>utf8_to_windows_1256</literal></entry>
2739        <entry><literal>UTF8</literal></entry>
2740        <entry><literal>WIN1256</literal></entry>
2741       </row>
2742
2743       <row>
2744        <entry><literal>utf8_to_windows_1257</literal></entry>
2745        <entry><literal>UTF8</literal></entry>
2746        <entry><literal>WIN1257</literal></entry>
2747       </row>
2748
2749       <row>
2750        <entry><literal>utf8_to_windows_866</literal></entry>
2751        <entry><literal>UTF8</literal></entry>
2752        <entry><literal>WIN866</literal></entry>
2753       </row>
2754
2755       <row>
2756        <entry><literal>utf8_to_windows_874</literal></entry>
2757        <entry><literal>UTF8</literal></entry>
2758        <entry><literal>WIN874</literal></entry>
2759       </row>
2760
2761       <row>
2762        <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
2763        <entry><literal>WIN1250</literal></entry>
2764        <entry><literal>LATIN2</literal></entry>
2765       </row>
2766
2767       <row>
2768        <entry><literal>windows_1250_to_mic</literal></entry>
2769        <entry><literal>WIN1250</literal></entry>
2770        <entry><literal>MULE_INTERNAL</literal></entry>
2771       </row>
2772
2773       <row>
2774        <entry><literal>windows_1250_to_utf8</literal></entry>
2775        <entry><literal>WIN1250</literal></entry>
2776        <entry><literal>UTF8</literal></entry>
2777       </row>
2778
2779       <row>
2780        <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
2781        <entry><literal>WIN1251</literal></entry>
2782        <entry><literal>ISO_8859_5</literal></entry>
2783       </row>
2784
2785       <row>
2786        <entry><literal>windows_1251_to_koi8_r</literal></entry>
2787        <entry><literal>WIN1251</literal></entry>
2788        <entry><literal>KOI8R</literal></entry>
2789       </row>
2790
2791       <row>
2792        <entry><literal>windows_1251_to_mic</literal></entry>
2793        <entry><literal>WIN1251</literal></entry>
2794        <entry><literal>MULE_INTERNAL</literal></entry>
2795       </row>
2796
2797       <row>
2798        <entry><literal>windows_1251_to_utf8</literal></entry>
2799        <entry><literal>WIN1251</literal></entry>
2800        <entry><literal>UTF8</literal></entry>
2801       </row>
2802
2803       <row>
2804        <entry><literal>windows_1251_to_windows_866</literal></entry>
2805        <entry><literal>WIN1251</literal></entry>
2806        <entry><literal>WIN866</literal></entry>
2807       </row>
2808
2809       <row>
2810        <entry><literal>windows_1252_to_utf8</literal></entry>
2811        <entry><literal>WIN1252</literal></entry>
2812        <entry><literal>UTF8</literal></entry>
2813       </row>
2814
2815       <row>
2816        <entry><literal>windows_1256_to_utf8</literal></entry>
2817        <entry><literal>WIN1256</literal></entry>
2818        <entry><literal>UTF8</literal></entry>
2819       </row>
2820
2821       <row>
2822        <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2823        <entry><literal>WIN866</literal></entry>
2824        <entry><literal>ISO_8859_5</literal></entry>
2825       </row>
2826
2827       <row>
2828        <entry><literal>windows_866_to_koi8_r</literal></entry>
2829        <entry><literal>WIN866</literal></entry>
2830        <entry><literal>KOI8R</literal></entry>
2831       </row>
2832
2833       <row>
2834        <entry><literal>windows_866_to_mic</literal></entry>
2835        <entry><literal>WIN866</literal></entry>
2836        <entry><literal>MULE_INTERNAL</literal></entry>
2837       </row>
2838
2839       <row>
2840        <entry><literal>windows_866_to_utf8</literal></entry>
2841        <entry><literal>WIN866</literal></entry>
2842        <entry><literal>UTF8</literal></entry>
2843       </row>
2844
2845       <row>
2846        <entry><literal>windows_866_to_windows_1251</literal></entry>
2847        <entry><literal>WIN866</literal></entry>
2848        <entry><literal>WIN</literal></entry>
2849       </row>
2850
2851       <row>
2852        <entry><literal>windows_874_to_utf8</literal></entry>
2853        <entry><literal>WIN874</literal></entry>
2854        <entry><literal>UTF8</literal></entry>
2855       </row>
2856
2857       <row>
2858        <entry><literal>euc_jis_2004_to_utf8</literal></entry>
2859        <entry><literal>EUC_JIS_2004</literal></entry>
2860        <entry><literal>UTF8</literal></entry>
2861       </row>
2862
2863       <row>
2864        <entry><literal>utf8_to_euc_jis_2004</literal></entry>
2865        <entry><literal>UTF8</literal></entry>
2866        <entry><literal>EUC_JIS_2004</literal></entry>
2867       </row>
2868
2869       <row>
2870        <entry><literal>shift_jis_2004_to_utf8</literal></entry>
2871        <entry><literal>SHIFT_JIS_2004</literal></entry>
2872        <entry><literal>UTF8</literal></entry>
2873       </row>
2874
2875       <row>
2876        <entry><literal>utf8_to_shift_jis_2004</literal></entry>
2877        <entry><literal>UTF8</literal></entry>
2878        <entry><literal>SHIFT_JIS_2004</literal></entry>
2879       </row>
2880
2881       <row>
2882        <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
2883        <entry><literal>EUC_JIS_2004</literal></entry>
2884        <entry><literal>SHIFT_JIS_2004</literal></entry>
2885       </row>
2886
2887       <row>
2888        <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
2889        <entry><literal>SHIFT_JIS_2004</literal></entry>
2890        <entry><literal>EUC_JIS_2004</literal></entry>
2891       </row>
2892
2893      </tbody>
2894     </tgroup>
2895    </table>
2896
2897    <sect2 id="functions-string-format">
2898     <title><function>format</function></title>
2899
2900     <indexterm>
2901      <primary>format</primary>
2902     </indexterm>
2903
2904     <para>
2905      The function <function>format</> produces output formatted according to
2906      a format string, in a style similar to the C function
2907      <function>sprintf</>.
2908     </para>
2909
2910     <para>
2911 <synopsis>
2912 <function>format</>(<parameter>formatstr</> <type>text</> [, <parameter>formatarg</> <type>"any"</> [, ...] ])
2913 </synopsis>
2914      <replaceable>formatstr</> is a format string that specifies how the
2915      result should be formatted.  Text in the format string is copied
2916      directly to the result, except where <firstterm>format specifiers</> are
2917      used.  Format specifiers act as placeholders in the string, defining how
2918      subsequent function arguments should be formatted and inserted into the
2919      result.  Each <replaceable>formatarg</> argument is converted to text
2920      according to the usual output rules for its data type, and then formatted
2921      and inserted into the result string according to the format specifier(s).
2922     </para>
2923
2924     <para>
2925      Format specifiers are introduced by a <literal>%</> character and have
2926      the form
2927 <synopsis>
2928 %[<replaceable>position</>][<replaceable>flags</>][<replaceable>width</>]<replaceable>type</>
2929 </synopsis>
2930      where the component fields are:
2931
2932      <variablelist>
2933       <varlistentry>
2934        <term><replaceable>position</replaceable> (optional)</term>
2935        <listitem>
2936         <para>
2937          A string of the form <literal><replaceable>n</>$</> where
2938          <replaceable>n</> is the index of the argument to print.
2939          Index 1 means the first argument after
2940          <replaceable>formatstr</>.  If the <replaceable>position</> is
2941          omitted, the default is to use the next argument in sequence.
2942         </para>
2943        </listitem>
2944       </varlistentry>
2945
2946       <varlistentry>
2947        <term><replaceable>flags</replaceable> (optional)</term>
2948        <listitem>
2949         <para>
2950          Additional options controlling how the format specifier's output is
2951          formatted.  Currently the only supported flag is a minus sign
2952          (<literal>-</>) which will cause the format specifier's output to be
2953          left-justified.  This has no effect unless the <replaceable>width</>
2954          field is also specified.
2955         </para>
2956        </listitem>
2957       </varlistentry>
2958
2959       <varlistentry>
2960        <term><replaceable>width</replaceable> (optional)</term>
2961        <listitem>
2962         <para>
2963          Specifies the <emphasis>minimum</> number of characters to use to
2964          display the format specifier's output.  The output is padded on the
2965          left or right (depending on the <literal>-</> flag) with spaces as
2966          needed to fill the width.  A too-small width does not cause
2967          truncation of the output, but is simply ignored.  The width may be
2968          specified using any of the following: a positive integer; an
2969          asterisk (<literal>*</>) to use the next function argument as the
2970          width; or a string of the form <literal>*<replaceable>n</>$</> to
2971          use the <replaceable>n</>th function argument as the width.
2972         </para>
2973
2974         <para>
2975          If the width comes from a function argument, that argument is
2976          consumed before the argument that is used for the format specifier's
2977          value.  If the width argument is negative, the result is left
2978          aligned (as if the <literal>-</> flag had been specified) within a
2979          field of length <function>abs</>(<replaceable>width</replaceable>).
2980         </para>
2981        </listitem>
2982       </varlistentry>
2983
2984       <varlistentry>
2985        <term><replaceable>type</replaceable> (required)</term>
2986        <listitem>
2987         <para>
2988          The type of format conversion to use to produce the format
2989          specifier's output.  The following types are supported:
2990          <itemizedlist>
2991           <listitem>
2992            <para>
2993             <literal>s</literal> formats the argument value as a simple
2994             string.  A null value is treated as an empty string.
2995            </para>
2996           </listitem>
2997           <listitem>
2998            <para>
2999             <literal>I</literal> treats the argument value as an SQL
3000             identifier, double-quoting it if necessary.
3001             It is an error for the value to be null (equivalent to
3002             <function>quote_ident</>).
3003            </para>
3004           </listitem>
3005           <listitem>
3006            <para>
3007             <literal>L</literal> quotes the argument value as an SQL literal.
3008             A null value is displayed as the string <literal>NULL</>, without
3009             quotes (equivalent to <function>quote_nullable</function>).
3010            </para>
3011           </listitem>
3012          </itemizedlist>
3013         </para>
3014        </listitem>
3015       </varlistentry>
3016      </variablelist>
3017     </para>
3018
3019     <para>
3020      In addition to the format specifiers described above, the special sequence
3021      <literal>%%</> may be used to output a literal <literal>%</> character.
3022     </para>
3023
3024     <para>
3025      Here are some examples of the basic format conversions:
3026
3027 <screen>
3028 SELECT format('Hello %s', 'World');
3029 <lineannotation>Result: </lineannotation><computeroutput>Hello World</computeroutput>
3030
3031 SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
3032 <lineannotation>Result: </><computeroutput>Testing one, two, three, %</>
3033
3034 SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
3035 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO "Foo bar" VALUES('O''Reilly')</computeroutput>
3036
3037 SELECT format('INSERT INTO %I VALUES(%L)', 'locations', E'C:\\Program Files');
3038 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO locations VALUES(E'C:\\Program Files')</computeroutput>
3039 </screen>
3040     </para>
3041
3042     <para>
3043      Here are examples using <replaceable>width</replaceable> fields
3044      and the <literal>-</> flag:
3045
3046 <screen>
3047 SELECT format('|%10s|', 'foo');
3048 <lineannotation>Result: </><computeroutput>|       foo|</>
3049
3050 SELECT format('|%-10s|', 'foo');
3051 <lineannotation>Result: </><computeroutput>|foo       |</>
3052
3053 SELECT format('|%*s|', 10, 'foo');
3054 <lineannotation>Result: </><computeroutput>|       foo|</>
3055
3056 SELECT format('|%*s|', -10, 'foo');
3057 <lineannotation>Result: </><computeroutput>|foo       |</>
3058
3059 SELECT format('|%-*s|', 10, 'foo');
3060 <lineannotation>Result: </><computeroutput>|foo       |</>
3061
3062 SELECT format('|%-*s|', -10, 'foo');
3063 <lineannotation>Result: </><computeroutput>|foo       |</>
3064 </screen>
3065     </para>
3066
3067     <para>
3068      These examples show use of <replaceable>position</> fields:
3069
3070 <screen>
3071 SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three');
3072 <lineannotation>Result: </><computeroutput>Testing three, two, one</>
3073
3074 SELECT format('|%*2$s|', 'foo', 10, 'bar');
3075 <lineannotation>Result: </><computeroutput>|       bar|</>
3076
3077 SELECT format('|%1$*2$s|', 'foo', 10, 'bar');
3078 <lineannotation>Result: </><computeroutput>|       foo|</>
3079 </screen>
3080     </para>
3081
3082     <para>
3083      Unlike the standard C function <function>sprintf</>,
3084      <productname>PostgreSQL</>'s <function>format</> function allows format
3085      specifiers with and without <replaceable>position</> fields to be mixed
3086      in the same format string.  A format specifier without a
3087      <replaceable>position</> field always uses the next argument after the
3088      last argument consumed.
3089      In addition, the <function>format</> function does not require all
3090      function arguments to be used in the format string.
3091      For example:
3092
3093 <screen>
3094 SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three');
3095 <lineannotation>Result: </><computeroutput>Testing three, two, three</>
3096 </screen>
3097     </para>
3098
3099     <para>
3100      The <literal>%I</> and <literal>%L</> format specifiers are particularly
3101      useful for safely constructing dynamic SQL statements.  See
3102      <xref linkend="plpgsql-quote-literal-example">.
3103     </para>
3104    </sect2>
3105
3106   </sect1>
3107
3108
3109   <sect1 id="functions-binarystring">
3110    <title>Binary String Functions and Operators</title>
3111
3112    <indexterm zone="functions-binarystring">
3113     <primary>binary data</primary>
3114     <secondary>functions</secondary>
3115    </indexterm>
3116
3117    <para>
3118     This section describes functions and operators for examining and
3119     manipulating values of type <type>bytea</type>.
3120    </para>
3121
3122    <para>
3123     <acronym>SQL</acronym> defines some string functions that use
3124     key words, rather than commas, to separate
3125     arguments.  Details are in
3126     <xref linkend="functions-binarystring-sql">.
3127     <productname>PostgreSQL</> also provides versions of these functions
3128     that use the regular function invocation syntax
3129     (see <xref linkend="functions-binarystring-other">).
3130    </para>
3131
3132    <note>
3133     <para>
3134      The sample results shown on this page assume that the server parameter
3135      <link linkend="guc-bytea-output"><varname>bytea_output</></link> is set
3136      to <literal>escape</literal> (the traditional PostgreSQL format).
3137     </para>
3138    </note>
3139
3140    <table id="functions-binarystring-sql">
3141     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
3142     <tgroup cols="5">
3143      <thead>
3144       <row>
3145        <entry>Function</entry>
3146        <entry>Return Type</entry>
3147        <entry>Description</entry>
3148        <entry>Example</entry>
3149        <entry>Result</entry>
3150       </row>
3151      </thead>
3152
3153      <tbody>
3154       <row>
3155        <entry><literal><parameter>string</parameter> <literal>||</literal>
3156         <parameter>string</parameter></literal></entry>
3157        <entry> <type>bytea</type> </entry>
3158        <entry>
3159         String concatenation
3160         <indexterm>
3161          <primary>binary string</primary>
3162          <secondary>concatenation</secondary>
3163         </indexterm>
3164        </entry>
3165        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
3166        <entry><literal>\\Post'gres\000</literal></entry>
3167       </row>
3168
3169       <row>
3170        <entry>
3171         <indexterm>
3172          <primary>octet_length</primary>
3173         </indexterm>
3174         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
3175        </entry>
3176        <entry><type>int</type></entry>
3177        <entry>Number of bytes in binary string</entry>
3178        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
3179        <entry><literal>5</literal></entry>
3180       </row>
3181
3182       <row>
3183        <entry>
3184         <indexterm>
3185          <primary>overlay</primary>
3186         </indexterm>
3187         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
3188        </entry>
3189        <entry><type>bytea</type></entry>
3190        <entry>
3191         Replace substring
3192        </entry>
3193        <entry><literal>overlay(E'Th\\000omas'::bytea placing E'\\002\\003'::bytea from 2 for 3)</literal></entry>
3194        <entry><literal>T\\002\\003mas</literal></entry>
3195       </row>
3196
3197       <row>
3198        <entry>
3199         <indexterm>
3200          <primary>position</primary>
3201         </indexterm>
3202         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
3203        </entry>
3204        <entry><type>int</type></entry>
3205        <entry>Location of specified substring</entry>
3206       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
3207        <entry><literal>3</literal></entry>
3208       </row>
3209
3210       <row>
3211        <entry>
3212         <indexterm>
3213          <primary>substring</primary>
3214         </indexterm>
3215         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
3216        </entry>
3217        <entry><type>bytea</type></entry>
3218        <entry>
3219         Extract substring
3220        </entry>
3221        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
3222        <entry><literal>h\000o</literal></entry>
3223       </row>
3224
3225       <row>
3226        <entry>
3227         <indexterm>
3228          <primary>trim</primary>
3229         </indexterm>
3230         <literal><function>trim(<optional>both</optional>
3231         <parameter>bytes</parameter> from
3232         <parameter>string</parameter>)</function></literal>
3233        </entry>
3234        <entry><type>bytea</type></entry>
3235        <entry>
3236         Remove the longest string containing only the bytes in
3237         <parameter>bytes</parameter> from the start
3238         and end of <parameter>string</parameter>
3239        </entry>
3240        <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
3241        <entry><literal>Tom</literal></entry>
3242       </row>
3243      </tbody>
3244     </tgroup>
3245    </table>
3246
3247    <para>
3248     Additional binary string manipulation functions are available and
3249     are listed in <xref linkend="functions-binarystring-other">.  Some
3250     of them are used internally to implement the
3251     <acronym>SQL</acronym>-standard string functions listed in <xref
3252     linkend="functions-binarystring-sql">.
3253    </para>
3254
3255    <table id="functions-binarystring-other">
3256     <title>Other Binary String Functions</title>
3257     <tgroup cols="5">
3258      <thead>
3259       <row>
3260        <entry>Function</entry>
3261        <entry>Return Type</entry>
3262        <entry>Description</entry>
3263        <entry>Example</entry>
3264        <entry>Result</entry>
3265       </row>
3266      </thead>
3267
3268      <tbody>
3269       <row>
3270        <entry>
3271         <indexterm>
3272          <primary>btrim</primary>
3273         </indexterm>
3274         <literal><function>btrim(<parameter>string</parameter>
3275         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</function></literal>
3276        </entry>
3277        <entry><type>bytea</type></entry>
3278        <entry>
3279         Remove the longest string consisting only of bytes
3280         in <parameter>bytes</parameter> from the start and end of
3281         <parameter>string</parameter>
3282       </entry>
3283       <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
3284       <entry><literal>trim</literal></entry>
3285      </row>
3286
3287      <row>
3288       <entry>
3289         <indexterm>
3290          <primary>decode</primary>
3291         </indexterm>
3292        <literal><function>decode(<parameter>string</parameter> <type>text</type>,
3293        <parameter>format</parameter> <type>text</type>)</function></literal>
3294       </entry>
3295       <entry><type>bytea</type></entry>
3296       <entry>
3297        Decode binary data from textual representation in <parameter>string</>.
3298        Options for <parameter>format</> are same as in <function>encode</>.
3299       </entry>
3300       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
3301       <entry><literal>123\000456</literal></entry>
3302      </row>
3303
3304      <row>
3305       <entry>
3306         <indexterm>
3307          <primary>encode</primary>
3308         </indexterm>
3309        <literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
3310        <parameter>format</parameter> <type>text</type>)</function></literal>
3311       </entry>
3312       <entry><type>text</type></entry>
3313       <entry>
3314        Encode binary data into a textual representation.  Supported
3315        formats are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
3316        <literal>escape</> converts zero bytes and high-bit-set bytes to
3317        octal sequences (<literal>\</><replaceable>nnn</>) and
3318        doubles backslashes.
3319       </entry>
3320       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
3321       <entry><literal>123\000456</literal></entry>
3322      </row>
3323
3324       <row>
3325        <entry>
3326         <indexterm>
3327          <primary>get_bit</primary>
3328         </indexterm>
3329         <literal><function>get_bit(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3330        </entry>
3331        <entry><type>int</type></entry>
3332        <entry>
3333         Extract bit from string
3334        </entry>
3335        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
3336        <entry><literal>1</literal></entry>
3337       </row>
3338
3339       <row>
3340        <entry>
3341         <indexterm>
3342          <primary>get_byte</primary>
3343         </indexterm>
3344         <literal><function>get_byte(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3345        </entry>
3346        <entry><type>int</type></entry>
3347        <entry>
3348         Extract byte from string
3349        </entry>
3350        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
3351        <entry><literal>109</literal></entry>
3352       </row>
3353
3354      <row>
3355       <entry>
3356        <indexterm>
3357         <primary>length</primary>
3358        </indexterm>
3359        <literal><function>length(<parameter>string</parameter>)</function></literal>
3360       </entry>
3361       <entry><type>int</type></entry>
3362       <entry>
3363        Length of binary string
3364        <indexterm>
3365         <primary>binary string</primary>
3366         <secondary>length</secondary>
3367        </indexterm>
3368        <indexterm>
3369         <primary>length</primary>
3370         <secondary sortas="binary string">of a binary string</secondary>
3371         <see>binary strings, length</see>
3372        </indexterm>
3373       </entry>
3374       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
3375       <entry><literal>5</literal></entry>
3376      </row>
3377
3378      <row>
3379       <entry>
3380        <indexterm>
3381         <primary>md5</primary>
3382        </indexterm>
3383        <literal><function>md5(<parameter>string</parameter>)</function></literal>
3384       </entry>
3385       <entry><type>text</type></entry>
3386       <entry>
3387        Calculates the MD5 hash of <parameter>string</parameter>,
3388        returning the result in hexadecimal
3389       </entry>
3390       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
3391       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
3392      </row>
3393
3394       <row>
3395        <entry>
3396         <indexterm>
3397          <primary>set_bit</primary>
3398         </indexterm>
3399         <literal><function>set_bit(<parameter>string</parameter>,
3400         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3401        </entry>
3402        <entry><type>bytea</type></entry>
3403        <entry>
3404         Set bit in string
3405        </entry>
3406        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
3407        <entry><literal>Th\000omAs</literal></entry>
3408       </row>
3409
3410       <row>
3411        <entry>
3412         <indexterm>
3413          <primary>set_byte</primary>
3414         </indexterm>
3415         <literal><function>set_byte(<parameter>string</parameter>,
3416         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3417        </entry>
3418        <entry><type>bytea</type></entry>
3419        <entry>
3420         Set byte in string
3421        </entry>
3422        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
3423        <entry><literal>Th\000o@as</literal></entry>
3424       </row>
3425     </tbody>
3426    </tgroup>
3427   </table>
3428
3429   <para>
3430    <function>get_byte</> and <function>set_byte</> number the first byte
3431    of a binary string as byte 0.
3432    <function>get_bit</> and <function>set_bit</> number bits from the
3433    right within each byte; for example bit 0 is the least significant bit of
3434    the first byte, and bit 15 is the most significant bit of the second byte.
3435   </para>
3436
3437   <para>
3438    See also the aggregate function <function>string_agg</function> in
3439    <xref linkend="functions-aggregate"> and the large object functions
3440    in <xref linkend="lo-funcs">.
3441   </para>
3442  </sect1>
3443
3444
3445   <sect1 id="functions-bitstring">
3446    <title>Bit String Functions and Operators</title>
3447
3448    <indexterm zone="functions-bitstring">
3449     <primary>bit strings</primary>
3450     <secondary>functions</secondary>
3451    </indexterm>
3452
3453    <para>
3454     This section describes functions and operators for examining and
3455     manipulating bit strings, that is values of the types
3456     <type>bit</type> and <type>bit varying</type>.  Aside from the
3457     usual comparison operators, the operators
3458     shown in <xref linkend="functions-bit-string-op-table"> can be used.
3459     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
3460     and <literal>#</literal> must be of equal length.  When bit
3461     shifting, the original length of the string is preserved, as shown
3462     in the examples.
3463    </para>
3464
3465    <table id="functions-bit-string-op-table">
3466     <title>Bit String Operators</title>
3467
3468     <tgroup cols="4">
3469      <thead>
3470       <row>
3471        <entry>Operator</entry>
3472        <entry>Description</entry>
3473        <entry>Example</entry>
3474        <entry>Result</entry>
3475       </row>
3476      </thead>
3477
3478      <tbody>
3479       <row>
3480        <entry> <literal>||</literal> </entry>
3481        <entry>concatenation</entry>
3482        <entry><literal>B'10001' || B'011'</literal></entry>
3483        <entry><literal>10001011</literal></entry>
3484       </row>
3485
3486       <row>
3487        <entry> <literal>&amp;</literal> </entry>
3488        <entry>bitwise AND</entry>
3489        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
3490        <entry><literal>00001</literal></entry>
3491       </row>
3492
3493       <row>
3494        <entry> <literal>|</literal> </entry>
3495        <entry>bitwise OR</entry>
3496        <entry><literal>B'10001' | B'01101'</literal></entry>
3497        <entry><literal>11101</literal></entry>
3498       </row>
3499
3500       <row>
3501        <entry> <literal>#</literal> </entry>
3502        <entry>bitwise XOR</entry>
3503        <entry><literal>B'10001' # B'01101'</literal></entry>
3504        <entry><literal>11100</literal></entry>
3505       </row>
3506
3507       <row>
3508        <entry> <literal>~</literal> </entry>
3509        <entry>bitwise NOT</entry>
3510        <entry><literal>~ B'10001'</literal></entry>
3511        <entry><literal>01110</literal></entry>
3512       </row>
3513
3514       <row>
3515        <entry> <literal>&lt;&lt;</literal> </entry>
3516        <entry>bitwise shift left</entry>
3517        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
3518        <entry><literal>01000</literal></entry>
3519       </row>
3520
3521       <row>
3522        <entry> <literal>&gt;&gt;</literal> </entry>
3523        <entry>bitwise shift right</entry>
3524        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
3525        <entry><literal>00100</literal></entry>
3526       </row>
3527      </tbody>
3528     </tgroup>
3529    </table>
3530
3531    <para>
3532     The following <acronym>SQL</acronym>-standard functions work on bit
3533     strings as well as character strings:
3534     <literal><function>length</function></literal>,
3535     <literal><function>bit_length</function></literal>,
3536     <literal><function>octet_length</function></literal>,
3537     <literal><function>position</function></literal>,
3538     <literal><function>substring</function></literal>,
3539     <literal><function>overlay</function></literal>.
3540    </para>
3541
3542    <para>
3543     The following functions work on bit strings as well as binary
3544     strings:
3545     <literal><function>get_bit</function></literal>,
3546     <literal><function>set_bit</function></literal>.
3547     When working with a bit string, these functions number the first
3548     (leftmost) bit of the string as bit 0.
3549    </para>
3550
3551    <para>
3552     In addition, it is possible to cast integral values to and from type
3553     <type>bit</>.
3554     Some examples:
3555 <programlisting>
3556 44::bit(10)                    <lineannotation>0000101100</lineannotation>
3557 44::bit(3)                     <lineannotation>100</lineannotation>
3558 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
3559 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
3560 </programlisting>
3561     Note that casting to just <quote>bit</> means casting to
3562     <literal>bit(1)</>, and so will deliver only the least significant
3563     bit of the integer.
3564    </para>
3565
3566     <note>
3567      <para>
3568       Casting an integer to <type>bit(n)</> copies the rightmost
3569       <literal>n</> bits.  Casting an integer to a bit string width wider
3570       than the integer itself will sign-extend on the left.
3571      </para>
3572     </note>
3573
3574   </sect1>
3575
3576
3577  <sect1 id="functions-matching">
3578   <title>Pattern Matching</title>
3579
3580   <indexterm zone="functions-matching">
3581    <primary>pattern matching</primary>
3582   </indexterm>
3583
3584    <para>
3585     There are three separate approaches to pattern matching provided
3586     by <productname>PostgreSQL</productname>: the traditional
3587     <acronym>SQL</acronym> <function>LIKE</function> operator, the
3588     more recent <function>SIMILAR TO</function> operator (added in
3589     SQL:1999), and <acronym>POSIX</acronym>-style regular
3590     expressions.  Aside from the basic <quote>does this string match
3591     this pattern?</> operators, functions are available to extract
3592     or replace matching substrings and to split a string at matching
3593     locations.
3594    </para>
3595
3596    <tip>
3597     <para>
3598      If you have pattern matching needs that go beyond this,
3599      consider writing a user-defined function in Perl or Tcl.
3600     </para>
3601    </tip>
3602
3603   <sect2 id="functions-like">
3604    <title><function>LIKE</function></title>
3605
3606    <indexterm>
3607     <primary>LIKE</primary>
3608    </indexterm>
3609
3610 <synopsis>
3611 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3612 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3613 </synopsis>
3614
3615     <para>
3616      The <function>LIKE</function> expression returns true if the
3617      <replaceable>string</replaceable> matches the supplied
3618      <replaceable>pattern</replaceable>.  (As
3619      expected, the <function>NOT LIKE</function> expression returns
3620      false if <function>LIKE</function> returns true, and vice versa.
3621      An equivalent expression is
3622      <literal>NOT (<replaceable>string</replaceable> LIKE
3623       <replaceable>pattern</replaceable>)</literal>.)
3624     </para>
3625
3626     <para>
3627      If <replaceable>pattern</replaceable> does not contain percent
3628      signs or underscores, then the pattern only represents the string
3629      itself; in that case <function>LIKE</function> acts like the
3630      equals operator.  An underscore (<literal>_</literal>) in
3631      <replaceable>pattern</replaceable> stands for (matches) any single
3632      character; a percent sign (<literal>%</literal>) matches any sequence
3633      of zero or more characters.
3634     </para>
3635
3636    <para>
3637     Some examples:
3638 <programlisting>
3639 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
3640 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
3641 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
3642 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
3643 </programlisting>
3644    </para>
3645
3646    <para>
3647     <function>LIKE</function> pattern matching always covers the entire
3648     string.  Therefore, if it's desired to match a sequence anywhere within
3649     a string, the pattern must start and end with a percent sign.
3650    </para>
3651
3652    <para>
3653     To match a literal underscore or percent sign without matching
3654     other characters, the respective character in
3655     <replaceable>pattern</replaceable> must be
3656     preceded by the escape character.  The default escape
3657     character is the backslash but a different one can be selected by
3658     using the <literal>ESCAPE</literal> clause.  To match the escape
3659     character itself, write two escape characters.
3660    </para>
3661
3662    <note>
3663     <para>
3664      If you have <xref linkend="guc-standard-conforming-strings"> turned off,
3665      any backslashes you write in literal string constants will need to be
3666      doubled.  See <xref linkend="sql-syntax-strings"> for more information.
3667     </para>
3668    </note>
3669
3670    <para>
3671     It's also possible to select no escape character by writing
3672     <literal>ESCAPE ''</literal>.  This effectively disables the
3673     escape mechanism, which makes it impossible to turn off the
3674     special meaning of underscore and percent signs in the pattern.
3675    </para>
3676
3677    <para>
3678     The key word <token>ILIKE</token> can be used instead of
3679     <token>LIKE</token> to make the match case-insensitive according
3680     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3681     <productname>PostgreSQL</productname> extension.
3682    </para>
3683
3684    <para>
3685     The operator <literal>~~</literal> is equivalent to
3686     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3687     <function>ILIKE</function>.  There are also
3688     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3689     represent <function>NOT LIKE</function> and <function>NOT
3690     ILIKE</function>, respectively.  All of these operators are
3691     <productname>PostgreSQL</productname>-specific.
3692    </para>
3693   </sect2>
3694
3695
3696   <sect2 id="functions-similarto-regexp">
3697    <title><function>SIMILAR TO</function> Regular Expressions</title>
3698
3699    <indexterm>
3700     <primary>regular expression</primary>
3701     <!-- <seealso>pattern matching</seealso> breaks index build -->
3702    </indexterm>
3703
3704    <indexterm>
3705     <primary>SIMILAR TO</primary>
3706    </indexterm>
3707    <indexterm>
3708     <primary>substring</primary>
3709    </indexterm>
3710
3711 <synopsis>
3712 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3713 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3714 </synopsis>
3715
3716    <para>
3717     The <function>SIMILAR TO</function> operator returns true or
3718     false depending on whether its pattern matches the given string.
3719     It is similar to <function>LIKE</function>, except that it
3720     interprets the pattern using the SQL standard's definition of a
3721     regular expression.  SQL regular expressions are a curious cross
3722     between <function>LIKE</function> notation and common regular
3723     expression notation.
3724    </para>
3725
3726    <para>
3727     Like <function>LIKE</function>, the <function>SIMILAR TO</function>
3728     operator succeeds only if its pattern matches the entire string;
3729     this is unlike common regular expression behavior where the pattern
3730     can match any part of the string.
3731     Also like
3732     <function>LIKE</function>, <function>SIMILAR TO</function> uses
3733     <literal>_</> and <literal>%</> as wildcard characters denoting
3734     any single character and any string, respectively (these are
3735     comparable to <literal>.</> and <literal>.*</> in POSIX regular
3736     expressions).
3737    </para>
3738
3739    <para>
3740     In addition to these facilities borrowed from <function>LIKE</function>,
3741     <function>SIMILAR TO</function> supports these pattern-matching
3742     metacharacters borrowed from POSIX regular expressions:
3743
3744    <itemizedlist>
3745     <listitem>
3746      <para>
3747       <literal>|</literal> denotes alternation (either of two alternatives).
3748      </para>
3749     </listitem>
3750     <listitem>
3751      <para>
3752       <literal>*</literal> denotes repetition of the previous item zero
3753       or more times.
3754      </para>
3755     </listitem>
3756     <listitem>
3757      <para>
3758       <literal>+</literal> denotes repetition of the previous item one
3759       or more times.
3760      </para>
3761     </listitem>
3762     <listitem>
3763      <para>
3764       <literal>?</literal> denotes repetition of the previous item zero
3765       or one time.
3766      </para>
3767     </listitem>
3768     <listitem>
3769      <para>
3770       <literal>{</><replaceable>m</><literal>}</literal> denotes repetition
3771       of the previous item exactly <replaceable>m</> times.
3772      </para>
3773     </listitem>
3774     <listitem>
3775      <para>
3776       <literal>{</><replaceable>m</><literal>,}</literal> denotes repetition
3777       of the previous item <replaceable>m</> or more times.
3778      </para>
3779     </listitem>
3780     <listitem>
3781      <para>
3782       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
3783       denotes repetition of the previous item at least <replaceable>m</> and
3784       not more than <replaceable>n</> times.
3785      </para>
3786     </listitem>
3787     <listitem>
3788      <para>
3789       Parentheses <literal>()</literal> can be used to group items into
3790       a single logical item.
3791      </para>
3792     </listitem>
3793     <listitem>
3794      <para>
3795       A bracket expression <literal>[...]</literal> specifies a character
3796       class, just as in POSIX regular expressions.
3797      </para>
3798     </listitem>
3799    </itemizedlist>
3800
3801     Notice that the period (<literal>.</>) is not a metacharacter
3802     for <function>SIMILAR TO</>.
3803    </para>
3804
3805    <para>
3806     As with <function>LIKE</>, a backslash disables the special meaning
3807     of any of these metacharacters; or a different escape character can
3808     be specified with <literal>ESCAPE</>.
3809    </para>
3810
3811    <para>
3812     Some examples:
3813 <programlisting>
3814 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
3815 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
3816 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
3817 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
3818 </programlisting>
3819    </para>
3820
3821    <para>
3822     The <function>substring</> function with three parameters,
3823     <function>substring(<replaceable>string</replaceable> from
3824     <replaceable>pattern</replaceable> for
3825     <replaceable>escape-character</replaceable>)</function>, provides
3826     extraction of a substring that matches an SQL
3827     regular expression pattern.  As with <literal>SIMILAR TO</>, the
3828     specified pattern must match the entire data string, or else the
3829     function fails and returns null.  To indicate the part of the
3830     pattern that should be returned on success, the pattern must contain
3831     two occurrences of the escape character followed by a double quote
3832     (<literal>"</>). <!-- " font-lock sanity -->
3833     The text matching the portion of the pattern
3834     between these markers is returned.
3835    </para>
3836
3837    <para>
3838     Some examples, with <literal>#&quot;</> delimiting the return string:
3839 <programlisting>
3840 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
3841 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
3842 </programlisting>
3843    </para>
3844   </sect2>
3845
3846   <sect2 id="functions-posix-regexp">
3847    <title><acronym>POSIX</acronym> Regular Expressions</title>
3848
3849    <indexterm zone="functions-posix-regexp">
3850     <primary>regular expression</primary>
3851     <seealso>pattern matching</seealso>
3852    </indexterm>
3853    <indexterm>
3854     <primary>substring</primary>
3855    </indexterm>
3856    <indexterm>
3857     <primary>regexp_replace</primary>
3858    </indexterm>
3859    <indexterm>
3860     <primary>regexp_matches</primary>
3861    </indexterm>
3862    <indexterm>
3863     <primary>regexp_split_to_table</primary>
3864    </indexterm>
3865    <indexterm>
3866     <primary>regexp_split_to_array</primary>
3867    </indexterm>
3868
3869    <para>
3870     <xref linkend="functions-posix-table"> lists the available
3871     operators for pattern matching using POSIX regular expressions.
3872    </para>
3873
3874    <table id="functions-posix-table">
3875     <title>Regular Expression Match Operators</title>
3876
3877     <tgroup cols="3">
3878      <thead>
3879       <row>
3880        <entry>Operator</entry>
3881        <entry>Description</entry>
3882        <entry>Example</entry>
3883       </row>
3884      </thead>
3885
3886       <tbody>
3887        <row>
3888         <entry> <literal>~</literal> </entry>
3889         <entry>Matches regular expression, case sensitive</entry>
3890         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3891        </row>
3892
3893        <row>
3894         <entry> <literal>~*</literal> </entry>
3895         <entry>Matches regular expression, case insensitive</entry>
3896         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3897        </row>
3898
3899        <row>
3900         <entry> <literal>!~</literal> </entry>
3901         <entry>Does not match regular expression, case sensitive</entry>
3902         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3903        </row>
3904
3905        <row>
3906         <entry> <literal>!~*</literal> </entry>
3907         <entry>Does not match regular expression, case insensitive</entry>
3908         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3909        </row>
3910       </tbody>
3911      </tgroup>
3912     </table>
3913
3914     <para>
3915      <acronym>POSIX</acronym> regular expressions provide a more
3916      powerful means for pattern matching than the <function>LIKE</function> and
3917      <function>SIMILAR TO</> operators.
3918      Many Unix tools such as <command>egrep</command>,
3919      <command>sed</command>, or <command>awk</command> use a pattern
3920      matching language that is similar to the one described here.
3921     </para>
3922
3923     <para>
3924      A regular expression is a character sequence that is an
3925      abbreviated definition of a set of strings (a <firstterm>regular
3926      set</firstterm>).  A string is said to match a regular expression
3927      if it is a member of the regular set described by the regular
3928      expression.  As with <function>LIKE</function>, pattern characters
3929      match string characters exactly unless they are special characters
3930      in the regular expression language &mdash; but regular expressions use
3931      different special characters than <function>LIKE</function> does.
3932      Unlike <function>LIKE</function> patterns, a
3933      regular expression is allowed to match anywhere within a string, unless
3934      the regular expression is explicitly anchored to the beginning or
3935      end of the string.
3936     </para>
3937
3938     <para>
3939      Some examples:
3940 <programlisting>
3941 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
3942 'abc' ~ '^a'     <lineannotation>true</lineannotation>
3943 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
3944 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3945 </programlisting>
3946     </para>
3947
3948     <para>
3949      The <acronym>POSIX</acronym> pattern language is described in much
3950      greater detail below.
3951     </para>
3952
3953     <para>
3954      The <function>substring</> function with two parameters,
3955      <function>substring(<replaceable>string</replaceable> from
3956      <replaceable>pattern</replaceable>)</function>, provides extraction of a
3957      substring
3958      that matches a POSIX regular expression pattern.  It returns null if
3959      there is no match, otherwise the portion of the text that matched the
3960      pattern.  But if the pattern contains any parentheses, the portion
3961      of the text that matched the first parenthesized subexpression (the
3962      one whose left parenthesis comes first) is
3963      returned.  You can put parentheses around the whole expression
3964      if you want to use parentheses within it without triggering this
3965      exception.  If you need parentheses in the pattern before the
3966      subexpression you want to extract, see the non-capturing parentheses
3967      described below.
3968     </para>
3969
3970    <para>
3971     Some examples:
3972 <programlisting>
3973 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
3974 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
3975 </programlisting>
3976    </para>
3977
3978     <para>
3979      The <function>regexp_replace</> function provides substitution of
3980      new text for substrings that match POSIX regular expression patterns.
3981      It has the syntax
3982      <function>regexp_replace</function>(<replaceable>source</>,
3983      <replaceable>pattern</>, <replaceable>replacement</>
3984      <optional>, <replaceable>flags</> </optional>).
3985      The <replaceable>source</> string is returned unchanged if
3986      there is no match to the <replaceable>pattern</>.  If there is a
3987      match, the <replaceable>source</> string is returned with the
3988      <replaceable>replacement</> string substituted for the matching
3989      substring.  The <replaceable>replacement</> string can contain
3990      <literal>\</><replaceable>n</>, where <replaceable>n</> is 1
3991      through 9, to indicate that the source substring matching the
3992      <replaceable>n</>'th parenthesized subexpression of the pattern should be
3993      inserted, and it can contain <literal>\&amp;</> to indicate that the
3994      substring matching the entire pattern should be inserted.  Write
3995      <literal>\\</> if you need to put a literal backslash in the replacement
3996      text.
3997      The <replaceable>flags</> parameter is an optional text
3998      string containing zero or more single-letter flags that change the
3999      function's behavior.  Flag <literal>i</> specifies case-insensitive
4000      matching, while flag <literal>g</> specifies replacement of each matching
4001      substring rather than only the first one.  Supported flags (though
4002      not <literal>g</>) are
4003      described in <xref linkend="posix-embedded-options-table">.
4004     </para>
4005
4006    <para>
4007     Some examples:
4008 <programlisting>
4009 regexp_replace('foobarbaz', 'b..', 'X')
4010                                    <lineannotation>fooXbaz</lineannotation>
4011 regexp_replace('foobarbaz', 'b..', 'X', 'g')
4012                                    <lineannotation>fooXX</lineannotation>
4013 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
4014                                    <lineannotation>fooXarYXazY</lineannotation>
4015 </programlisting>
4016    </para>
4017
4018     <para>
4019      The <function>regexp_matches</> function returns a text array of
4020      all of the captured substrings resulting from matching a POSIX
4021      regular expression pattern.  It has the syntax
4022      <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
4023      <optional>, <replaceable>flags</> </optional>).
4024      The function can return no rows, one row, or multiple rows (see
4025      the <literal>g</> flag below).  If the <replaceable>pattern</>
4026      does not match, the function returns no rows.  If the pattern
4027      contains no parenthesized subexpressions, then each row
4028      returned is a single-element text array containing the substring
4029      matching the whole pattern.  If the pattern contains parenthesized
4030      subexpressions, the function returns a text array whose
4031      <replaceable>n</>'th element is the substring matching the
4032      <replaceable>n</>'th parenthesized subexpression of the pattern
4033      (not counting <quote>non-capturing</> parentheses; see below for
4034      details).
4035      The <replaceable>flags</> parameter is an optional text
4036      string containing zero or more single-letter flags that change the
4037      function's behavior.  Flag <literal>g</> causes the function to find
4038      each match in the string, not only the first one, and return a row for
4039      each such match.  Supported flags (though
4040      not <literal>g</>)
4041      are described in <xref linkend="posix-embedded-options-table">.
4042     </para>
4043
4044    <para>
4045     Some examples:
4046 <programlisting>
4047 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
4048  regexp_matches 
4049 ----------------
4050  {bar,beque}
4051 (1 row)
4052
4053 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
4054  regexp_matches 
4055 ----------------
4056  {bar,beque}
4057  {bazil,barf}
4058 (2 rows)
4059
4060 SELECT regexp_matches('foobarbequebaz', 'barbeque');
4061  regexp_matches 
4062 ----------------
4063  {barbeque}
4064 (1 row)
4065 </programlisting>
4066    </para>
4067
4068    <para>
4069     It is possible to force <function>regexp_matches()</> to always
4070     return one row by using a sub-select;  this is particularly useful
4071     in a <literal>SELECT</> target list when you want all rows
4072     returned, even non-matching ones:
4073 <programlisting>
4074 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
4075 </programlisting>
4076    </para>
4077
4078     <para>
4079      The <function>regexp_split_to_table</> function splits a string using a POSIX
4080      regular expression pattern as a delimiter.  It has the syntax
4081      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
4082      <optional>, <replaceable>flags</> </optional>).
4083      If there is no match to the <replaceable>pattern</>, the function returns the
4084      <replaceable>string</>.  If there is at least one match, for each match it returns
4085      the text from the end of the last match (or the beginning of the string)
4086      to the beginning of the match.  When there are no more matches, it
4087      returns the text from the end of the last match to the end of the string.
4088      The <replaceable>flags</> parameter is an optional text string containing
4089      zero or more single-letter flags that change the function's behavior.
4090      <function>regexp_split_to_table</function> supports the flags described in
4091      <xref linkend="posix-embedded-options-table">.
4092     </para>
4093
4094     <para>
4095      The <function>regexp_split_to_array</> function behaves the same as
4096      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
4097      returns its result as an array of <type>text</>.  It has the syntax
4098      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
4099      <optional>, <replaceable>flags</> </optional>).
4100      The parameters are the same as for <function>regexp_split_to_table</>.
4101     </para>
4102
4103    <para>
4104     Some examples:
4105 <programlisting>
4106
4107 SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', E'\\s+') AS foo;
4108   foo   
4109 -------
4110  the    
4111  quick  
4112  brown  
4113  fox    
4114  jumps 
4115  over   
4116  the    
4117  lazy   
4118  dog    
4119 (9 rows)
4120
4121 SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', E'\\s+');
4122               regexp_split_to_array             
4123 -----------------------------------------------
4124  {the,quick,brown,fox,jumps,over,the,lazy,dog}
4125 (1 row)
4126
4127 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
4128  foo 
4129 -----
4130  t         
4131  h         
4132  e         
4133  q         
4134  u         
4135  i         
4136  c         
4137  k         
4138  b         
4139  r         
4140  o         
4141  w         
4142  n         
4143  f         
4144  o         
4145  x         
4146 (16 rows)
4147 </programlisting>
4148    </para>
4149
4150    <para>
4151     As the last example demonstrates, the regexp split functions ignore
4152     zero-length matches that occur at the start or end of the string
4153     or immediately after a previous match.  This is contrary to the strict
4154     definition of regexp matching that is implemented by
4155     <function>regexp_matches</>, but is usually the most convenient behavior
4156     in practice.  Other software systems such as Perl use similar definitions.
4157    </para>
4158
4159 <!-- derived from the re_syntax.n man page -->
4160
4161    <sect3 id="posix-syntax-details">
4162     <title>Regular Expression Details</title>
4163
4164    <para>
4165     <productname>PostgreSQL</productname>'s regular expressions are implemented
4166     using a software package written by Henry Spencer.  Much of
4167     the description of regular expressions below is copied verbatim from his
4168     manual.
4169    </para>
4170
4171    <para>
4172     Regular expressions (<acronym>RE</acronym>s), as defined in
4173     <acronym>POSIX</acronym> 1003.2, come in two forms:
4174     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
4175     (roughly those of <command>egrep</command>), and
4176     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
4177     (roughly those of <command>ed</command>).
4178     <productname>PostgreSQL</productname> supports both forms, and
4179     also implements some extensions
4180     that are not in the POSIX standard, but have become widely used
4181     due to their availability in programming languages such as Perl and Tcl.
4182     <acronym>RE</acronym>s using these non-POSIX extensions are called
4183     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
4184     in this documentation.  AREs are almost an exact superset of EREs,
4185     but BREs have several notational incompatibilities (as well as being
4186     much more limited).
4187     We first describe the ARE and ERE forms, noting features that apply
4188     only to AREs, and then describe how BREs differ.
4189    </para>
4190
4191    <note>
4192     <para>
4193      <productname>PostgreSQL</> always initially presumes that a regular
4194      expression follows the ARE rules.  However, the more limited ERE or
4195      BRE rules can be chosen by prepending an <firstterm>embedded option</>
4196      to the RE pattern, as described in <xref linkend="posix-metasyntax">.
4197      This can be useful for compatibility with applications that expect
4198      exactly the <acronym>POSIX</acronym> 1003.2 rules.
4199     </para>
4200    </note>
4201
4202    <para>
4203     A regular expression is defined as one or more
4204     <firstterm>branches</firstterm>, separated by
4205     <literal>|</literal>.  It matches anything that matches one of the
4206     branches.
4207    </para>
4208
4209    <para>
4210     A branch is zero or more <firstterm>quantified atoms</> or
4211     <firstterm>constraints</>, concatenated.
4212     It matches a match for the first, followed by a match for the second, etc;
4213     an empty branch matches the empty string.
4214    </para>
4215
4216    <para>
4217     A quantified atom is an <firstterm>atom</> possibly followed
4218     by a single <firstterm>quantifier</>.
4219     Without a quantifier, it matches a match for the atom.
4220     With a quantifier, it can match some number of matches of the atom.
4221     An <firstterm>atom</firstterm> can be any of the possibilities
4222     shown in <xref linkend="posix-atoms-table">.
4223     The possible quantifiers and their meanings are shown in
4224     <xref linkend="posix-quantifiers-table">.
4225    </para>
4226
4227    <para>
4228     A <firstterm>constraint</> matches an empty string, but matches only when
4229     specific conditions are met.  A constraint can be used where an atom
4230     could be used, except it cannot be followed by a quantifier.
4231     The simple constraints are shown in
4232     <xref linkend="posix-constraints-table">;
4233     some more constraints are described later.
4234    </para>
4235
4236
4237    <table id="posix-atoms-table">
4238     <title>Regular Expression Atoms</title>
4239
4240     <tgroup cols="2">
4241      <thead>
4242       <row>
4243        <entry>Atom</entry>
4244        <entry>Description</entry>
4245       </row>
4246      </thead>
4247
4248       <tbody>
4249        <row>
4250        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
4251        <entry> (where <replaceable>re</> is any regular expression)
4252        matches a match for
4253        <replaceable>re</>, with the match noted for possible reporting </entry>
4254        </row>
4255
4256        <row>
4257        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
4258        <entry> as above, but the match is not noted for reporting
4259        (a <quote>non-capturing</> set of parentheses)
4260        (AREs only) </entry>
4261        </row>
4262
4263        <row>
4264        <entry> <literal>.</> </entry>
4265        <entry> matches any single character </entry>
4266        </row>
4267
4268        <row>
4269        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
4270        <entry> a <firstterm>bracket expression</>,
4271        matching any one of the <replaceable>chars</> (see
4272        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
4273        </row>
4274
4275        <row>
4276        <entry> <literal>\</><replaceable>k</> </entry>
4277        <entry> (where <replaceable>k</> is a non-alphanumeric character)
4278        matches that character taken as an ordinary character,
4279        e.g., <literal>\\</> matches a backslash character </entry>
4280        </row>
4281
4282        <row>
4283        <entry> <literal>\</><replaceable>c</> </entry>
4284        <entry> where <replaceable>c</> is alphanumeric
4285        (possibly followed by other characters)
4286        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
4287        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
4288        </row>
4289
4290        <row>
4291        <entry> <literal>{</> </entry>
4292        <entry> when followed by a character other than a digit,
4293        matches the left-brace character <literal>{</>;
4294        when followed by a digit, it is the beginning of a
4295        <replaceable>bound</> (see below) </entry>
4296        </row>
4297
4298        <row>
4299        <entry> <replaceable>x</> </entry>
4300        <entry> where <replaceable>x</> is a single character with no other
4301        significance, matches that character </entry>
4302        </row>
4303       </tbody>
4304      </tgroup>
4305     </table>
4306
4307    <para>
4308     An RE cannot end with a backslash (<literal>\</>).
4309    </para>
4310
4311    <note>
4312     <para>
4313      If you have <xref linkend="guc-standard-conforming-strings"> turned off,
4314      any backslashes you write in literal string constants will need to be
4315      doubled.  See <xref linkend="sql-syntax-strings"> for more information.
4316     </para>
4317    </note>
4318
4319    <table id="posix-quantifiers-table">
4320     <title>Regular Expression Quantifiers</title>
4321
4322     <tgroup cols="2">
4323      <thead>
4324       <row>
4325        <entry>Quantifier</entry>
4326        <entry>Matches</entry>
4327       </row>
4328      </thead>
4329
4330       <tbody>
4331        <row>
4332        <entry> <literal>*</> </entry>
4333        <entry> a sequence of 0 or more matches of the atom </entry>
4334        </row>
4335
4336        <row>
4337        <entry> <literal>+</> </entry>
4338        <entry> a sequence of 1 or more matches of the atom </entry>
4339        </row>
4340
4341        <row>
4342        <entry> <literal>?</> </entry>
4343        <entry> a sequence of 0 or 1 matches of the atom </entry>
4344        </row>
4345
4346        <row>
4347        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
4348        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
4349        </row>
4350
4351        <row>
4352        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
4353        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
4354        </row>
4355
4356        <row>
4357        <entry>
4358        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4359        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
4360        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
4361        <replaceable>n</> </entry>
4362        </row>
4363
4364        <row>
4365        <entry> <literal>*?</> </entry>
4366        <entry> non-greedy version of <literal>*</> </entry>
4367        </row>
4368
4369        <row>
4370        <entry> <literal>+?</> </entry>
4371        <entry> non-greedy version of <literal>+</> </entry>
4372        </row>
4373
4374        <row>
4375        <entry> <literal>??</> </entry>
4376        <entry> non-greedy version of <literal>?</> </entry>
4377        </row>
4378
4379        <row>
4380        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
4381        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
4382        </row>
4383
4384        <row>
4385        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
4386        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
4387        </row>
4388
4389        <row>
4390        <entry>
4391        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
4392        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4393        </row>
4394       </tbody>
4395      </tgroup>
4396     </table>
4397
4398    <para>
4399     The forms using <literal>{</><replaceable>...</><literal>}</>
4400     are known as <firstterm>bounds</>.
4401     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
4402     unsigned decimal integers with permissible values from 0 to 255 inclusive.
4403    </para>
4404
4405     <para>
4406      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
4407      same possibilities as their corresponding normal (<firstterm>greedy</>)
4408      counterparts, but prefer the smallest number rather than the largest
4409      number of matches.
4410      See <xref linkend="posix-matching-rules"> for more detail.
4411    </para>
4412
4413    <note>
4414     <para>
4415      A quantifier cannot immediately follow another quantifier, e.g.,
4416      <literal>**</> is invalid.
4417      A quantifier cannot
4418      begin an expression or subexpression or follow
4419      <literal>^</literal> or <literal>|</literal>.
4420     </para>
4421    </note>
4422
4423    <table id="posix-constraints-table">
4424     <title>Regular Expression Constraints</title>
4425
4426     <tgroup cols="2">
4427      <thead>
4428       <row>
4429        <entry>Constraint</entry>
4430        <entry>Description</entry>
4431       </row>
4432      </thead>
4433
4434       <tbody>
4435        <row>
4436        <entry> <literal>^</> </entry>
4437        <entry> matches at the beginning of the string </entry>
4438        </row>
4439
4440        <row>
4441        <entry> <literal>$</> </entry>
4442        <entry> matches at the end of the string </entry>
4443        </row>
4444
4445        <row>
4446        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
4447        <entry> <firstterm>positive lookahead</> matches at any point
4448        where a substring matching <replaceable>re</> begins
4449        (AREs only) </entry>
4450        </row>
4451
4452        <row>
4453        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
4454        <entry> <firstterm>negative lookahead</> matches at any point
4455        where no substring matching <replaceable>re</> begins
4456        (AREs only) </entry>
4457        </row>
4458       </tbody>
4459      </tgroup>
4460     </table>
4461
4462    <para>
4463     Lookahead constraints cannot contain <firstterm>back references</>
4464     (see <xref linkend="posix-escape-sequences">),
4465     and all parentheses within them are considered non-capturing.
4466    </para>
4467    </sect3>
4468
4469    <sect3 id="posix-bracket-expressions">
4470     <title>Bracket Expressions</title>
4471
4472    <para>
4473     A <firstterm>bracket expression</firstterm> is a list of
4474     characters enclosed in <literal>[]</literal>.  It normally matches
4475     any single character from the list (but see below).  If the list
4476     begins with <literal>^</literal>, it matches any single character
4477     <emphasis>not</> from the rest of the list.
4478     If two characters
4479     in the list are separated by <literal>-</literal>, this is
4480     shorthand for the full range of characters between those two
4481     (inclusive) in the collating sequence,
4482     e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
4483     any decimal digit.  It is illegal for two ranges to share an
4484     endpoint, e.g.,  <literal>a-c-e</literal>.  Ranges are very
4485     collating-sequence-dependent, so portable programs should avoid
4486     relying on them.
4487    </para>
4488
4489    <para>
4490     To include a literal <literal>]</literal> in the list, make it the
4491     first character (after <literal>^</literal>, if that is used).  To
4492     include a literal <literal>-</literal>, make it the first or last
4493     character, or the second endpoint of a range.  To use a literal
4494     <literal>-</literal> as the first endpoint of a range, enclose it
4495     in <literal>[.</literal> and <literal>.]</literal> to make it a
4496     collating element (see below).  With the exception of these characters,
4497     some combinations using <literal>[</literal>
4498     (see next paragraphs), and escapes (AREs only), all other special
4499     characters lose their special significance within a bracket expression.
4500     In particular, <literal>\</literal> is not special when following
4501     ERE or BRE rules, though it is special (as introducing an escape)
4502     in AREs.
4503    </para>
4504
4505    <para>
4506     Within a bracket expression, a collating element (a character, a
4507     multiple-character sequence that collates as if it were a single
4508     character, or a collating-sequence name for either) enclosed in
4509     <literal>[.</literal> and <literal>.]</literal> stands for the
4510     sequence of characters of that collating element.  The sequence is
4511     treated as a single element of the bracket expression's list.  This
4512     allows a bracket
4513     expression containing a multiple-character collating element to
4514     match more than one character, e.g., if the collating sequence
4515     includes a <literal>ch</literal> collating element, then the RE
4516     <literal>[[.ch.]]*c</literal> matches the first five characters of
4517     <literal>chchcc</literal>.
4518    </para>
4519
4520    <note>
4521     <para>
4522      <productname>PostgreSQL</> currently does not support multi-character collating
4523      elements. This information describes possible future behavior.
4524     </para>
4525    </note>
4526
4527    <para>
4528     Within a bracket expression, a collating element enclosed in
4529     <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
4530     class</>, standing for the sequences of characters of all collating
4531     elements equivalent to that one, including itself.  (If there are
4532     no other equivalent collating elements, the treatment is as if the
4533     enclosing delimiters were <literal>[.</literal> and
4534     <literal>.]</literal>.)  For example, if <literal>o</literal> and
4535     <literal>^</literal> are the members of an equivalence class, then
4536     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
4537     <literal>[o^]</literal> are all synonymous.  An equivalence class
4538     cannot be an endpoint of a range.
4539    </para>
4540
4541    <para>
4542     Within a bracket expression, the name of a character class
4543     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
4544     for the list of all characters belonging to that class.  Standard
4545     character class names are: <literal>alnum</literal>,
4546     <literal>alpha</literal>, <literal>blank</literal>,
4547     <literal>cntrl</literal>, <literal>digit</literal>,
4548     <literal>graph</literal>, <literal>lower</literal>,
4549     <literal>print</literal>, <literal>punct</literal>,
4550     <literal>space</literal>, <literal>upper</literal>,
4551     <literal>xdigit</literal>.  These stand for the character classes
4552     defined in
4553     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
4554     A locale can provide others.  A character class cannot be used as
4555     an endpoint of a range.
4556    </para>
4557
4558    <para>
4559     There are two special cases of bracket expressions:  the bracket
4560     expressions <literal>[[:&lt;:]]</literal> and
4561     <literal>[[:&gt;:]]</literal> are constraints,
4562     matching empty strings at the beginning
4563     and end of a word respectively.  A word is defined as a sequence
4564     of word characters that is neither preceded nor followed by word
4565     characters.  A word character is an <literal>alnum</> character (as
4566     defined by
4567     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
4568     or an underscore.  This is an extension, compatible with but not
4569     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
4570     caution in software intended to be portable to other systems.
4571     The constraint escapes described below are usually preferable; they
4572     are no more standard, but are easier to type.
4573    </para>
4574    </sect3>
4575
4576    <sect3 id="posix-escape-sequences">
4577     <title>Regular Expression Escapes</title>
4578
4579    <para>
4580     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
4581     followed by an alphanumeric character. Escapes come in several varieties:
4582     character entry, class shorthands, constraint escapes, and back references.
4583     A <literal>\</> followed by an alphanumeric character but not constituting
4584     a valid escape is illegal in AREs.
4585     In EREs, there are no escapes: outside a bracket expression,
4586     a <literal>\</> followed by an alphanumeric character merely stands for
4587     that character as an ordinary character, and inside a bracket expression,
4588     <literal>\</> is an ordinary character.
4589     (The latter is the one actual incompatibility between EREs and AREs.)
4590    </para>
4591
4592    <para>
4593     <firstterm>Character-entry escapes</> exist to make it easier to specify
4594     non-printing and other inconvenient characters in REs.  They are
4595     shown in <xref linkend="posix-character-entry-escapes-table">.
4596    </para>
4597
4598    <para>
4599     <firstterm>Class-shorthand escapes</> provide shorthands for certain
4600     commonly-used character classes.  They are
4601     shown in <xref linkend="posix-class-shorthand-escapes-table">.
4602    </para>
4603
4604    <para>
4605     A <firstterm>constraint escape</> is a constraint,
4606     matching the empty string if specific conditions are met,
4607     written as an escape.  They are
4608     shown in <xref linkend="posix-constraint-escapes-table">.
4609    </para>
4610
4611    <para>
4612     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
4613     same string matched by the previous parenthesized subexpression specified
4614     by the number <replaceable>n</>
4615     (see <xref linkend="posix-constraint-backref-table">).  For example,
4616     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
4617     but not <literal>bc</> or <literal>cb</>.
4618     The subexpression must entirely precede the back reference in the RE.
4619     Subexpressions are numbered in the order of their leading parentheses.
4620     Non-capturing parentheses do not define subexpressions.
4621    </para>
4622
4623    <note>
4624     <para>
4625      Keep in mind that an escape's leading <literal>\</> will need to be
4626      doubled when entering the pattern as an SQL string constant.  For example:
4627 <programlisting>
4628 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
4629 </programlisting>
4630     </para>
4631    </note>
4632
4633    <table id="posix-character-entry-escapes-table">
4634     <title>Regular Expression Character-entry Escapes</title>
4635
4636     <tgroup cols="2">
4637      <thead>
4638       <row>
4639        <entry>Escape</entry>
4640        <entry>Description</entry>
4641       </row>
4642      </thead>
4643
4644       <tbody>
4645        <row>
4646        <entry> <literal>\a</> </entry>
4647        <entry> alert (bell) character, as in C </entry>
4648        </row>
4649
4650        <row>
4651        <entry> <literal>\b</> </entry>
4652        <entry> backspace, as in C </entry>
4653        </row>
4654
4655        <row>
4656        <entry> <literal>\B</> </entry>
4657        <entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
4658        doubling </entry>
4659        </row>
4660
4661        <row>
4662        <entry> <literal>\c</><replaceable>X</> </entry>
4663        <entry> (where <replaceable>X</> is any character) the character whose
4664        low-order 5 bits are the same as those of
4665        <replaceable>X</>, and whose other bits are all zero </entry>
4666        </row>
4667
4668        <row>
4669        <entry> <literal>\e</> </entry>
4670        <entry> the character whose collating-sequence name
4671        is <literal>ESC</>,
4672        or failing that, the character with octal value 033 </entry>
4673        </row>
4674
4675        <row>
4676        <entry> <literal>\f</> </entry>
4677        <entry> form feed, as in C </entry>
4678        </row>
4679
4680        <row>
4681        <entry> <literal>\n</> </entry>
4682        <entry> newline, as in C </entry>
4683        </row>
4684
4685        <row>
4686        <entry> <literal>\r</> </entry>
4687        <entry> carriage return, as in C </entry>
4688        </row>
4689
4690        <row>
4691        <entry> <literal>\t</> </entry>
4692        <entry> horizontal tab, as in C </entry>
4693        </row>
4694
4695        <row>
4696        <entry> <literal>\u</><replaceable>wxyz</> </entry>
4697        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4698        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4699        in the local byte ordering </entry>
4700        </row>
4701
4702        <row>
4703        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4704        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4705        digits)
4706        reserved for a hypothetical Unicode extension to 32 bits
4707        </entry>
4708        </row>
4709
4710        <row>
4711        <entry> <literal>\v</> </entry>
4712        <entry> vertical tab, as in C </entry>
4713        </row>
4714
4715        <row>
4716        <entry> <literal>\x</><replaceable>hhh</> </entry>
4717        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4718        digits)
4719        the character whose hexadecimal value is
4720        <literal>0x</><replaceable>hhh</>
4721        (a single character no matter how many hexadecimal digits are used)
4722        </entry>
4723        </row>
4724
4725        <row>
4726        <entry> <literal>\0</> </entry>
4727        <entry> the character whose value is <literal>0</> (the null byte)</entry>
4728        </row>
4729
4730        <row>
4731        <entry> <literal>\</><replaceable>xy</> </entry>
4732        <entry> (where <replaceable>xy</> is exactly two octal digits,
4733        and is not a <firstterm>back reference</>)
4734        the character whose octal value is
4735        <literal>0</><replaceable>xy</> </entry>
4736        </row>
4737
4738        <row>
4739        <entry> <literal>\</><replaceable>xyz</> </entry>
4740        <entry> (where <replaceable>xyz</> is exactly three octal digits,
4741        and is not a <firstterm>back reference</>)
4742        the character whose octal value is
4743        <literal>0</><replaceable>xyz</> </entry>
4744        </row>
4745       </tbody>
4746      </tgroup>
4747     </table>
4748
4749    <para>
4750     Hexadecimal digits are <literal>0</>-<literal>9</>,
4751     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4752     Octal digits are <literal>0</>-<literal>7</>.
4753    </para>
4754
4755    <para>
4756     The character-entry escapes are always taken as ordinary characters.
4757     For example, <literal>\135</> is <literal>]</> in ASCII, but
4758     <literal>\135</> does not terminate a bracket expression.
4759    </para>
4760
4761    <table id="posix-class-shorthand-escapes-table">
4762     <title>Regular Expression Class-shorthand Escapes</title>
4763
4764     <tgroup cols="2">
4765      <thead>
4766       <row>
4767        <entry>Escape</entry>
4768        <entry>Description</entry>
4769       </row>
4770      </thead>
4771
4772       <tbody>
4773        <row>
4774        <entry> <literal>\d</> </entry>
4775        <entry> <literal>[[:digit:]]</> </entry>
4776        </row>
4777
4778        <row>
4779        <entry> <literal>\s</> </entry>
4780        <entry> <literal>[[:space:]]</> </entry>
4781        </row>
4782
4783        <row>
4784        <entry> <literal>\w</> </entry>
4785        <entry> <literal>[[:alnum:]_]</>
4786        (note underscore is included) </entry>
4787        </row>
4788
4789        <row>
4790        <entry> <literal>\D</> </entry>
4791        <entry> <literal>[^[:digit:]]</> </entry>
4792        </row>
4793
4794        <row>
4795        <entry> <literal>\S</> </entry>
4796        <entry> <literal>[^[:space:]]</> </entry>
4797        </row>
4798
4799        <row>
4800        <entry> <literal>\W</> </entry>
4801        <entry> <literal>[^[:alnum:]_]</>
4802        (note underscore is included) </entry>
4803        </row>
4804       </tbody>
4805      </tgroup>
4806     </table>
4807
4808    <para>
4809     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4810     and <literal>\w</> lose their outer brackets,
4811     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4812     (So, for example, <literal>[a-c\d]</> is equivalent to
4813     <literal>[a-c[:digit:]]</>.
4814     Also, <literal>[a-c\D]</>, which is equivalent to
4815     <literal>[a-c^[:digit:]]</>, is illegal.)
4816    </para>
4817
4818    <table id="posix-constraint-escapes-table">
4819     <title>Regular Expression Constraint Escapes</title>
4820
4821     <tgroup cols="2">
4822      <thead>
4823       <row>
4824        <entry>Escape</entry>
4825        <entry>Description</entry>
4826       </row>
4827      </thead>
4828
4829       <tbody>
4830        <row>
4831        <entry> <literal>\A</> </entry>
4832        <entry> matches only at the beginning of the string
4833        (see <xref linkend="posix-matching-rules"> for how this differs from
4834        <literal>^</>) </entry>
4835        </row>
4836
4837        <row>
4838        <entry> <literal>\m</> </entry>
4839        <entry> matches only at the beginning of a word </entry>
4840        </row>
4841
4842        <row>
4843        <entry> <literal>\M</> </entry>
4844        <entry> matches only at the end of a word </entry>
4845        </row>
4846
4847        <row>
4848        <entry> <literal>\y</> </entry>
4849        <entry> matches only at the beginning or end of a word </entry>
4850        </row>
4851
4852        <row>
4853        <entry> <literal>\Y</> </entry>
4854        <entry> matches only at a point that is not the beginning or end of a
4855        word </entry>
4856        </row>
4857
4858        <row>
4859        <entry> <literal>\Z</> </entry>
4860        <entry> matches only at the end of the string
4861        (see <xref linkend="posix-matching-rules"> for how this differs from
4862        <literal>$</>) </entry>
4863        </row>
4864       </tbody>
4865      </tgroup>
4866     </table>
4867
4868    <para>
4869     A word is defined as in the specification of
4870     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4871     Constraint escapes are illegal within bracket expressions.
4872    </para>
4873
4874    <table id="posix-constraint-backref-table">
4875     <title>Regular Expression Back References</title>
4876
4877     <tgroup cols="2">
4878      <thead>
4879       <row>
4880        <entry>Escape</entry>
4881        <entry>Description</entry>
4882       </row>
4883      </thead>
4884
4885       <tbody>
4886        <row>
4887        <entry> <literal>\</><replaceable>m</> </entry>
4888        <entry> (where <replaceable>m</> is a nonzero digit)
4889        a back reference to the <replaceable>m</>'th subexpression </entry>
4890        </row>
4891
4892        <row>
4893        <entry> <literal>\</><replaceable>mnn</> </entry>
4894        <entry> (where <replaceable>m</> is a nonzero digit, and
4895        <replaceable>nn</> is some more digits, and the decimal value
4896        <replaceable>mnn</> is not greater than the number of closing capturing
4897        parentheses seen so far)
4898        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4899        </row>
4900       </tbody>
4901      </tgroup>
4902     </table>
4903
4904    <note>
4905     <para>
4906      There is an inherent ambiguity between octal character-entry
4907      escapes and back references, which is resolved by the following heuristics,
4908      as hinted at above.
4909      A leading zero always indicates an octal escape.
4910      A single non-zero digit, not followed by another digit,
4911      is always taken as a back reference.
4912      A multi-digit sequence not starting with a zero is taken as a back
4913      reference if it comes after a suitable subexpression
4914      (i.e., the number is in the legal range for a back reference),
4915      and otherwise is taken as octal.
4916     </para>
4917    </note>
4918    </sect3>
4919
4920    <sect3 id="posix-metasyntax">
4921     <title>Regular Expression Metasyntax</title>
4922
4923    <para>
4924     In addition to the main syntax described above, there are some special
4925     forms and miscellaneous syntactic facilities available.
4926    </para>
4927
4928    <para>
4929     An RE can begin with one of two special <firstterm>director</> prefixes.
4930     If an RE begins with <literal>***:</>,
4931     the rest of the RE is taken as an ARE.  (This normally has no effect in
4932     <productname>PostgreSQL</>, since REs are assumed to be AREs;
4933     but it does have an effect if ERE or BRE mode had been specified by
4934     the <replaceable>flags</> parameter to a regex function.)
4935     If an RE begins with <literal>***=</>,
4936     the rest of the RE is taken to be a literal string,
4937     with all characters considered ordinary characters.
4938    </para>
4939
4940    <para>
4941     An ARE can begin with <firstterm>embedded options</>:
4942     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4943     (where <replaceable>xyz</> is one or more alphabetic characters)
4944     specifies options affecting the rest of the RE.
4945     These options override any previously determined options &mdash;
4946     in particular, they can override the case-sensitivity behavior implied by
4947     a regex operator, or the <replaceable>flags</> parameter to a regex
4948     function.
4949     The available option letters are
4950     shown in <xref linkend="posix-embedded-options-table">.
4951     Note that these same option letters are used in the <replaceable>flags</>
4952     parameters of regex functions.
4953    </para>
4954
4955    <table id="posix-embedded-options-table">
4956     <title>ARE Embedded-option Letters</title>
4957
4958     <tgroup cols="2">
4959      <thead>
4960       <row>
4961        <entry>Option</entry>
4962        <entry>Description</entry>
4963       </row>
4964      </thead>
4965
4966       <tbody>
4967        <row>
4968        <entry> <literal>b</> </entry>
4969        <entry> rest of RE is a BRE </entry>
4970        </row>
4971
4972        <row>
4973        <entry> <literal>c</> </entry>
4974        <entry> case-sensitive matching (overrides operator type) </entry>
4975        </row>
4976
4977        <row>
4978        <entry> <literal>e</> </entry>
4979        <entry> rest of RE is an ERE </entry>
4980        </row>
4981
4982        <row>
4983        <entry> <literal>i</> </entry>
4984        <entry> case-insensitive matching (see
4985        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4986        </row>
4987
4988        <row>
4989        <entry> <literal>m</> </entry>
4990        <entry> historical synonym for <literal>n</> </entry>
4991        </row>
4992
4993        <row>
4994        <entry> <literal>n</> </entry>
4995        <entry> newline-sensitive matching (see
4996        <xref linkend="posix-matching-rules">) </entry>
4997        </row>
4998
4999        <row>
5000        <entry> <literal>p</> </entry>
5001        <entry> partial newline-sensitive matching (see
5002        <xref linkend="posix-matching-rules">) </entry>
5003        </row>
5004
5005        <row>
5006        <entry> <literal>q</> </entry>
5007        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
5008        characters </entry>
5009        </row>
5010
5011        <row>
5012        <entry> <literal>s</> </entry>
5013        <entry> non-newline-sensitive matching (default) </entry>
5014        </row>
5015
5016        <row>
5017        <entry> <literal>t</> </entry>
5018        <entry> tight syntax (default; see below) </entry>
5019        </row>
5020
5021        <row>
5022        <entry> <literal>w</> </entry>
5023        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
5024        (see <xref linkend="posix-matching-rules">) </entry>
5025        </row>
5026
5027        <row>
5028        <entry> <literal>x</> </entry>
5029        <entry> expanded syntax (see below) </entry>
5030        </row>
5031       </tbody>
5032      </tgroup>
5033     </table>
5034
5035    <para>
5036     Embedded options take effect at the <literal>)</> terminating the sequence.
5037     They can appear only at the start of an ARE (after the
5038     <literal>***:</> director if any).
5039    </para>
5040
5041    <para>
5042     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
5043     characters are significant, there is an <firstterm>expanded</> syntax,
5044     available by specifying the embedded <literal>x</> option.
5045     In the expanded syntax,
5046     white-space characters in the RE are ignored, as are
5047     all characters between a <literal>#</>
5048     and the following newline (or the end of the RE).  This
5049     permits paragraphing and commenting a complex RE.
5050     There are three exceptions to that basic rule:
5051
5052     <itemizedlist>
5053      <listitem>
5054       <para>
5055        a white-space character or <literal>#</> preceded by <literal>\</> is
5056        retained
5057       </para>
5058      </listitem>
5059      <listitem>
5060       <para>
5061        white space or <literal>#</> within a bracket expression is retained
5062       </para>
5063      </listitem>
5064      <listitem>
5065       <para>
5066        white space and comments cannot appear within multi-character symbols,
5067        such as <literal>(?:</>
5068       </para>
5069      </listitem>
5070     </itemizedlist>
5071
5072     For this purpose, white-space characters are blank, tab, newline, and
5073     any character that belongs to the <replaceable>space</> character class.
5074    </para>
5075
5076    <para>
5077     Finally, in an ARE, outside bracket expressions, the sequence
5078     <literal>(?#</><replaceable>ttt</><literal>)</>
5079     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
5080     is a comment, completely ignored.
5081     Again, this is not allowed between the characters of
5082     multi-character symbols, like <literal>(?:</>.
5083     Such comments are more a historical artifact than a useful facility,
5084     and their use is deprecated; use the expanded syntax instead.
5085    </para>
5086
5087    <para>
5088     <emphasis>None</> of these metasyntax extensions is available if
5089     an initial <literal>***=</> director
5090     has specified that the user's input be treated as a literal string
5091     rather than as an RE.
5092    </para>
5093    </sect3>
5094
5095    <sect3 id="posix-matching-rules">
5096     <title>Regular Expression Matching Rules</title>
5097
5098    <para>
5099     In the event that an RE could match more than one substring of a given
5100     string, the RE matches the one starting earliest in the string.
5101     If the RE could match more than one substring starting at that point,
5102     either the longest possible match or the shortest possible match will
5103     be taken, depending on whether the RE is <firstterm>greedy</> or
5104     <firstterm>non-greedy</>.
5105    </para>
5106
5107    <para>
5108     Whether an RE is greedy or not is determined by the following rules:
5109     <itemizedlist>
5110      <listitem>
5111       <para>
5112        Most atoms, and all constraints, have no greediness attribute (because
5113        they cannot match variable amounts of text anyway).
5114       </para>
5115      </listitem>
5116      <listitem>
5117       <para>
5118        Adding parentheses around an RE does not change its greediness.
5119       </para>
5120      </listitem>
5121      <listitem>
5122       <para>
5123        A quantified atom with a fixed-repetition quantifier
5124        (<literal>{</><replaceable>m</><literal>}</>
5125        or
5126        <literal>{</><replaceable>m</><literal>}?</>)
5127        has the same greediness (possibly none) as the atom itself.
5128       </para>
5129      </listitem>
5130      <listitem>
5131       <para>
5132        A quantified atom with other normal quantifiers (including
5133        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
5134        with <replaceable>m</> equal to <replaceable>n</>)
5135        is greedy (prefers longest match).
5136       </para>
5137      </listitem>
5138      <listitem>
5139       <para>
5140        A quantified atom with a non-greedy quantifier (including
5141        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
5142        with <replaceable>m</> equal to <replaceable>n</>)
5143        is non-greedy (prefers shortest match).
5144       </para>
5145      </listitem>
5146      <listitem>
5147       <para>
5148        A branch &mdash; that is, an RE that has no top-level
5149        <literal>|</> operator &mdash; has the same greediness as the first
5150        quantified atom in it that has a greediness attribute.
5151       </para>
5152      </listitem>
5153      <listitem>
5154       <para>
5155        An RE consisting of two or more branches connected by the
5156        <literal>|</> operator is always greedy.
5157       </para>
5158      </listitem>
5159     </itemizedlist>
5160    </para>
5161
5162    <para>
5163     The above rules associate greediness attributes not only with individual
5164     quantified atoms, but with branches and entire REs that contain quantified
5165     atoms.  What that means is that the matching is done in such a way that
5166     the branch, or whole RE, matches the longest or shortest possible
5167     substring <emphasis>as a whole</>.  Once the length of the entire match
5168     is determined, the part of it that matches any particular subexpression
5169     is determined on the basis of the greediness attribute of that
5170     subexpression, with subexpressions starting earlier in the RE taking
5171     priority over ones starting later.
5172    </para>
5173
5174    <para>
5175     An example of what this means:
5176 <screen>
5177 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
5178 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
5179 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
5180 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
5181 </screen>
5182     In the first case, the RE as a whole is greedy because <literal>Y*</>
5183     is greedy.  It can match beginning at the <literal>Y</>, and it matches
5184     the longest possible string starting there, i.e., <literal>Y123</>.
5185     The output is the parenthesized part of that, or <literal>123</>.
5186     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
5187     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
5188     the shortest possible string starting there, i.e., <literal>Y1</>.
5189     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
5190     the decision as to the overall match length; so it is forced to match
5191     just <literal>1</>.
5192    </para>
5193
5194    <para>
5195     In short, when an RE contains both greedy and non-greedy subexpressions,
5196     the total match length is either as long as possible or as short as
5197     possible, according to the attribute assigned to the whole RE.  The
5198     attributes assigned to the subexpressions only affect how much of that
5199     match they are allowed to <quote>eat</> relative to each other.
5200    </para>
5201
5202    <para>
5203     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
5204     can be used to force greediness or non-greediness, respectively,
5205     on a subexpression or a whole RE.
5206    </para>
5207
5208    <para>
5209     Match lengths are measured in characters, not collating elements.
5210     An empty string is considered longer than no match at all.
5211     For example:
5212     <literal>bb*</>
5213     matches the three middle characters of <literal>abbbc</>;
5214     <literal>(week|wee)(night|knights)</>
5215     matches all ten characters of <literal>weeknights</>;
5216     when <literal>(.*).*</>
5217     is matched against <literal>abc</> the parenthesized subexpression
5218     matches all three characters; and when
5219     <literal>(a*)*</> is matched against <literal>bc</>
5220     both the whole RE and the parenthesized
5221     subexpression match an empty string.
5222    </para>
5223
5224    <para>
5225     If case-independent matching is specified,
5226     the effect is much as if all case distinctions had vanished from the
5227     alphabet.
5228     When an alphabetic that exists in multiple cases appears as an
5229     ordinary character outside a bracket expression, it is effectively
5230     transformed into a bracket expression containing both cases,
5231     e.g., <literal>x</> becomes <literal>[xX]</>.
5232     When it appears inside a bracket expression, all case counterparts
5233     of it are added to the bracket expression, e.g.,
5234     <literal>[x]</> becomes <literal>[xX]</>
5235     and <literal>[^x]</> becomes <literal>[^xX]</>.
5236    </para>
5237
5238    <para>
5239     If newline-sensitive matching is specified, <literal>.</>
5240     and bracket expressions using <literal>^</>
5241     will never match the newline character
5242     (so that matches will never cross newlines unless the RE
5243     explicitly arranges it)
5244     and <literal>^</> and <literal>$</>
5245     will match the empty string after and before a newline
5246     respectively, in addition to matching at beginning and end of string
5247     respectively.
5248     But the ARE escapes <literal>\A</> and <literal>\Z</>
5249     continue to match beginning or end of string <emphasis>only</>.
5250    </para>
5251
5252    <para>
5253     If partial newline-sensitive matching is specified,
5254     this affects <literal>.</> and bracket expressions
5255     as with newline-sensitive matching, but not <literal>^</>
5256     and <literal>$</>.
5257    </para>
5258
5259    <para>
5260     If inverse partial newline-sensitive matching is specified,
5261     this affects <literal>^</> and <literal>$</>
5262     as with newline-sensitive matching, but not <literal>.</>
5263     and bracket expressions.
5264     This isn't very useful but is provided for symmetry.
5265    </para>
5266    </sect3>
5267
5268    <sect3 id="posix-limits-compatibility">
5269     <title>Limits and Compatibility</title>
5270
5271    <para>
5272     No particular limit is imposed on the length of REs in this
5273     implementation.  However,
5274     programs intended to be highly portable should not employ REs longer
5275     than 256 bytes,
5276     as a POSIX-compliant implementation can refuse to accept such REs.
5277    </para>
5278
5279    <para>
5280     The only feature of AREs that is actually incompatible with
5281     POSIX EREs is that <literal>\</> does not lose its special
5282     significance inside bracket expressions.
5283     All other ARE features use syntax which is illegal or has
5284     undefined or unspecified effects in POSIX EREs;
5285     the <literal>***</> syntax of directors likewise is outside the POSIX
5286     syntax for both BREs and EREs.
5287    </para>
5288
5289    <para>
5290     Many of the ARE extensions are borrowed from Perl, but some have
5291     been changed to clean them up, and a few Perl extensions are not present.
5292     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
5293     the lack of special treatment for a trailing newline,
5294     the addition of complemented bracket expressions to the things
5295     affected by newline-sensitive matching,
5296     the restrictions on parentheses and back references in lookahead
5297     constraints, and the longest/shortest-match (rather than first-match)
5298     matching semantics.
5299    </para>
5300
5301    <para>
5302     Two significant incompatibilities exist between AREs and the ERE syntax
5303     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
5304
5305     <itemizedlist>
5306      <listitem>
5307       <para>
5308        In AREs, <literal>\</> followed by an alphanumeric character is either
5309        an escape or an error, while in previous releases, it was just another
5310        way of writing the alphanumeric.
5311        This should not be much of a problem because there was no reason to
5312        write such a sequence in earlier releases.
5313       </para>
5314      </listitem>
5315      <listitem>
5316       <para>
5317        In AREs, <literal>\</> remains a special character within
5318        <literal>[]</>, so a literal <literal>\</> within a bracket
5319        expression must be written <literal>\\</>.
5320       </para>
5321      </listitem>
5322     </itemizedlist>
5323    </para>
5324    </sect3>
5325
5326    <sect3 id="posix-basic-regexes">
5327     <title>Basic Regular Expressions</title>
5328
5329    <para>
5330     BREs differ from EREs in several respects.
5331     In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
5332     are ordinary characters and there is no equivalent
5333     for their functionality.
5334     The delimiters for bounds are
5335     <literal>\{</> and <literal>\}</>,
5336     with <literal>{</> and <literal>}</>
5337     by themselves ordinary characters.
5338     The parentheses for nested subexpressions are
5339     <literal>\(</> and <literal>\)</>,
5340     with <literal>(</> and <literal>)</> by themselves ordinary characters.
5341     <literal>^</> is an ordinary character except at the beginning of the
5342     RE or the beginning of a parenthesized subexpression,
5343     <literal>$</> is an ordinary character except at the end of the
5344     RE or the end of a parenthesized subexpression,
5345     and <literal>*</> is an ordinary character if it appears at the beginning
5346     of the RE or the beginning of a parenthesized subexpression
5347     (after a possible leading <literal>^</>).
5348     Finally, single-digit back references are available, and
5349     <literal>\&lt;</> and <literal>\&gt;</>
5350     are synonyms for
5351     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
5352     respectively; no other escapes are available in BREs.
5353    </para>
5354    </sect3>
5355
5356 <!-- end re_syntax.n man page -->
5357
5358   </sect2>
5359  </sect1>
5360
5361
5362   <sect1 id="functions-formatting">
5363    <title>Data Type Formatting Functions</title>
5364
5365    <indexterm>
5366     <primary>formatting</primary>
5367    </indexterm>
5368
5369    <para>
5370     The <productname>PostgreSQL</productname> formatting functions
5371     provide a powerful set of tools for converting various data types
5372     (date/time, integer, floating point, numeric) to formatted strings
5373     and for converting from formatted strings to specific data types.
5374     <xref linkend="functions-formatting-table"> lists them.
5375     These functions all follow a common calling convention: the first
5376     argument is the value to be formatted and the second argument is a
5377     template that defines the output or input format.
5378    </para>
5379    <para>
5380     A single-argument <function>to_timestamp</function> function is also
5381     available;  it accepts a
5382     <type>double precision</type> argument and converts from Unix epoch
5383     (seconds since 1970-01-01 00:00:00+00) to
5384     <type>timestamp with time zone</type>.
5385     (<type>Integer</type> Unix epochs are implicitly cast to
5386     <type>double precision</type>.)
5387    </para>
5388
5389     <table id="functions-formatting-table">
5390      <title>Formatting Functions</title>
5391      <tgroup cols="4">
5392       <thead>
5393        <row>
5394         <entry>Function</entry>
5395         <entry>Return Type</entry>
5396         <entry>Description</entry>
5397         <entry>Example</entry>
5398        </row>
5399       </thead>
5400       <tbody>
5401        <row>
5402         <entry>
5403          <indexterm>
5404           <primary>to_char</primary>
5405          </indexterm>
5406          <literal><function>to_char(<type>timestamp</type>, <type>text</type>)</function></literal>
5407         </entry>
5408         <entry><type>text</type></entry>
5409         <entry>convert time stamp to string</entry>
5410         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
5411        </row>
5412        <row>
5413         <entry><literal><function>to_char(<type>interval</type>, <type>text</type>)</function></literal></entry>
5414         <entry><type>text</type></entry>
5415         <entry>convert interval to string</entry>
5416         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
5417        </row>
5418        <row>
5419         <entry><literal><function>to_char(<type>int</type>, <type>text</type>)</function></literal></entry>
5420         <entry><type>text</type></entry>
5421         <entry>convert integer to string</entry>
5422         <entry><literal>to_char(125, '999')</literal></entry>
5423        </row>
5424        <row>
5425         <entry><literal><function>to_char</function>(<type>double precision</type>,
5426         <type>text</type>)</literal></entry>
5427         <entry><type>text</type></entry>
5428         <entry>convert real/double precision to string</entry>
5429         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
5430        </row>
5431        <row>
5432         <entry><literal><function>to_char(<type>numeric</type>, <type>text</type>)</function></literal></entry>
5433         <entry><type>text</type></entry>
5434         <entry>convert numeric to string</entry>
5435         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
5436        </row>
5437        <row>
5438         <entry>
5439          <indexterm>
5440           <primary>to_date</primary>
5441          </indexterm>
5442          <literal><function>to_date(<type>text</type>, <type>text</type>)</function></literal>
5443         </entry>
5444         <entry><type>date</type></entry>
5445         <entry>convert string to date</entry>
5446         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5447        </row>
5448        <row>
5449         <entry>
5450          <indexterm>
5451           <primary>to_number</primary>
5452          </indexterm>
5453          <literal><function>to_number(<type>text</type>, <type>text</type>)</function></literal>
5454         </entry>
5455         <entry><type>numeric</type></entry>
5456         <entry>convert string to numeric</entry>
5457         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
5458        </row>
5459        <row>
5460         <entry>
5461          <indexterm>
5462           <primary>to_timestamp</primary>
5463          </indexterm>
5464          <literal><function>to_timestamp(<type>text</type>, <type>text</type>)</function></literal>
5465         </entry>
5466         <entry><type>timestamp with time zone</type></entry>
5467         <entry>convert string to time stamp</entry>
5468         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5469        </row>
5470        <row>
5471         <entry><literal><function>to_timestamp(<type>double precision</type>)</function></literal></entry>
5472         <entry><type>timestamp with time zone</type></entry>
5473         <entry>convert Unix epoch to time stamp</entry>
5474         <entry><literal>to_timestamp(1284352323)</literal></entry>
5475        </row>
5476       </tbody>
5477      </tgroup>
5478     </table>
5479
5480    <para>
5481     In a <function>to_char</> output template string, there are certain
5482     patterns that are recognized and replaced with appropriately-formatted
5483     data based on the given value.  Any text that is not a template pattern is
5484     simply copied verbatim.  Similarly, in an input template string (for the
5485     other functions), template patterns identify the values to be supplied by
5486     the input data string.
5487    </para>
5488
5489   <para>
5490    <xref linkend="functions-formatting-datetime-table"> shows the
5491    template patterns available for formatting date and time values.
5492   </para>
5493
5494     <table id="functions-formatting-datetime-table">
5495      <title>Template Patterns for Date/Time Formatting</title>
5496      <tgroup cols="2">
5497       <thead>
5498        <row>
5499         <entry>Pattern</entry>
5500         <entry>Description</entry>
5501        </row>
5502       </thead>
5503       <tbody>
5504        <row>
5505         <entry><literal>HH</literal></entry>
5506         <entry>hour of day (01-12)</entry>
5507        </row>
5508        <row>
5509         <entry><literal>HH12</literal></entry>
5510         <entry>hour of day (01-12)</entry>
5511        </row>
5512        <row>
5513         <entry><literal>HH24</literal></entry>
5514         <entry>hour of day (00-23)</entry>
5515        </row>
5516        <row>
5517         <entry><literal>MI</literal></entry>
5518         <entry>minute (00-59)</entry>
5519        </row>
5520        <row>
5521         <entry><literal>SS</literal></entry>
5522         <entry>second (00-59)</entry>
5523        </row>
5524        <row>
5525         <entry><literal>MS</literal></entry>
5526         <entry>millisecond (000-999)</entry>
5527        </row>
5528        <row>
5529         <entry><literal>US</literal></entry>
5530         <entry>microsecond (000000-999999)</entry>
5531        </row>
5532        <row>
5533         <entry><literal>SSSS</literal></entry>
5534         <entry>seconds past midnight (0-86399)</entry>
5535        </row>
5536        <row>
5537         <entry><literal>AM</literal>, <literal>am</literal>,
5538         <literal>PM</literal> or <literal>pm</literal></entry>
5539         <entry>meridiem indicator (without periods)</entry>
5540        </row>
5541        <row>
5542         <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
5543         <literal>P.M.</literal> or <literal>p.m.</literal></entry>
5544         <entry>meridiem indicator (with periods)</entry>
5545        </row>
5546        <row>
5547         <entry><literal>Y,YYY</literal></entry>
5548         <entry>year (4 or more digits) with comma</entry>
5549        </row>
5550        <row>
5551         <entry><literal>YYYY</literal></entry>
5552         <entry>year (4 or more digits)</entry>
5553        </row>
5554        <row>
5555         <entry><literal>YYY</literal></entry>
5556         <entry>last 3 digits of year</entry>
5557        </row>
5558        <row>
5559         <entry><literal>YY</literal></entry>
5560         <entry>last 2 digits of year</entry>
5561        </row>
5562        <row>
5563         <entry><literal>Y</literal></entry>
5564         <entry>last digit of year</entry>
5565        </row>
5566        <row>
5567         <entry><literal>IYYY</literal></entry>
5568         <entry>ISO 8601 week-numbering year (4 or more digits)</entry>
5569        </row>
5570        <row>
5571         <entry><literal>IYY</literal></entry>
5572         <entry>last 3 digits of ISO 8601 week-numbering year</entry>
5573        </row>
5574        <row>
5575         <entry><literal>IY</literal></entry>
5576         <entry>last 2 digits of ISO 8601 week-numbering year</entry>
5577        </row>
5578        <row>
5579         <entry><literal>I</literal></entry>
5580         <entry>last digit of ISO 8601 week-numbering year</entry>
5581        </row>
5582        <row>
5583         <entry><literal>BC</literal>, <literal>bc</literal>,
5584         <literal>AD</literal> or <literal>ad</literal></entry>
5585         <entry>era indicator (without periods)</entry>
5586        </row>
5587        <row>
5588         <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
5589         <literal>A.D.</literal> or <literal>a.d.</literal></entry>
5590         <entry>era indicator (with periods)</entry>
5591        </row>
5592        <row>
5593         <entry><literal>MONTH</literal></entry>
5594         <entry>full upper case month name (blank-padded to 9 chars)</entry>
5595        </row>
5596        <row>
5597         <entry><literal>Month</literal></entry>
5598         <entry>full capitalized month name (blank-padded to 9 chars)</entry>
5599        </row>
5600        <row>
5601         <entry><literal>month</literal></entry>
5602         <entry>full lower case month name (blank-padded to 9 chars)</entry>
5603        </row>
5604        <row>
5605         <entry><literal>MON</literal></entry>
5606         <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
5607        </row>
5608        <row>
5609         <entry><literal>Mon</literal></entry>
5610         <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
5611        </row>
5612        <row>
5613         <entry><literal>mon</literal></entry>
5614         <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
5615        </row>
5616        <row>
5617         <entry><literal>MM</literal></entry>
5618         <entry>month number (01-12)</entry>
5619        </row>
5620        <row>
5621         <entry><literal>DAY</literal></entry>
5622         <entry>full upper case day name (blank-padded to 9 chars)</entry>
5623        </row>
5624        <row>
5625         <entry><literal>Day</literal></entry>
5626         <entry>full capitalized day name (blank-padded to 9 chars)</entry>
5627        </row>
5628        <row>
5629         <entry><literal>day</literal></entry>
5630         <entry>full lower case day name (blank-padded to 9 chars)</entry>
5631        </row>
5632        <row>
5633         <entry><literal>DY</literal></entry>
5634         <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
5635        </row>
5636        <row>
5637         <entry><literal>Dy</literal></entry>
5638         <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
5639        </row>
5640        <row>
5641         <entry><literal>dy</literal></entry>
5642         <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
5643        </row>
5644        <row>
5645         <entry><literal>DDD</literal></entry>
5646         <entry>day of year (001-366)</entry>
5647        </row>
5648        <row>
5649         <entry><literal>IDDD</literal></entry>
5650         <entry>day of ISO 8601 week-numbering year (001-371; day 1 of the year is Monday of the first ISO week)</entry>
5651        </row>
5652        <row>
5653         <entry><literal>DD</literal></entry>
5654         <entry>day of month (01-31)</entry>
5655        </row>
5656        <row>
5657         <entry><literal>D</literal></entry>
5658         <entry>day of the week, Sunday (<literal>1</>) to Saturday (<literal>7</>)</entry>
5659        </row>
5660        <row>
5661         <entry><literal>ID</literal></entry>
5662         <entry>ISO 8601 day of the week, Monday (<literal>1</>) to Sunday (<literal>7</>)</entry>
5663        </row>
5664        <row>
5665         <entry><literal>W</literal></entry>
5666         <entry>week of month (1-5) (the first week starts on the first day of the month)</entry>
5667        </row>
5668        <row>
5669         <entry><literal>WW</literal></entry>
5670         <entry>week number of year (1-53) (the first week starts on the first day of the year)</entry>
5671        </row>
5672        <row>
5673         <entry><literal>IW</literal></entry>
5674         <entry>week number of ISO 8601 week-numbering year (01-53; the first Thursday of the year is in week 1)</entry>
5675        </row>
5676        <row>
5677         <entry><literal>CC</literal></entry>
5678         <entry>century (2 digits) (the twenty-first century starts on 2001-01-01)</entry>
5679        </row>
5680        <row>
5681         <entry><literal>J</literal></entry>
5682         <entry>Julian Day (integer days since November 24, 4714 BC at midnight UTC)</entry>
5683        </row>
5684        <row>
5685         <entry><literal>Q</literal></entry>
5686         <entry>quarter (ignored by <function>to_date</> and <function>to_timestamp</>)</entry>
5687        </row>
5688        <row>
5689         <entry><literal>RM</literal></entry>
5690         <entry>month in upper case Roman numerals (I-XII; I=January)</entry>
5691        </row>
5692        <row>
5693         <entry><literal>rm</literal></entry>
5694         <entry>month in lower case Roman numerals (i-xii; i=January)</entry>
5695        </row>
5696        <row>
5697         <entry><literal>TZ</literal></entry>
5698         <entry>upper case time-zone name</entry>
5699        </row>
5700        <row>
5701         <entry><literal>tz</literal></entry>
5702         <entry>lower case time-zone name</entry>
5703        </row>
5704        <row>
5705         <entry><literal>OF</literal></entry>
5706         <entry>time-zone offset</entry>
5707        </row>
5708       </tbody>
5709      </tgroup>
5710     </table>
5711
5712    <para>
5713     Modifiers can be applied to any template pattern to alter its
5714     behavior.  For example, <literal>FMMonth</literal>
5715     is the <literal>Month</literal> pattern with the
5716     <literal>FM</literal> modifier.
5717     <xref linkend="functions-formatting-datetimemod-table"> shows the
5718     modifier patterns for date/time formatting.
5719    </para>
5720
5721     <table id="functions-formatting-datetimemod-table">
5722      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5723      <tgroup cols="3">
5724       <thead>
5725        <row>
5726         <entry>Modifier</entry>
5727         <entry>Description</entry>
5728         <entry>Example</entry>
5729        </row>
5730       </thead>
5731       <tbody>
5732        <row>
5733         <entry><literal>FM</literal> prefix</entry>
5734         <entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
5735         <entry><literal>FMMonth</literal></entry>
5736        </row>
5737        <row>
5738         <entry><literal>TH</literal> suffix</entry>
5739         <entry>upper case ordinal number suffix</entry>
5740         <entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
5741        </row>
5742        <row>
5743         <entry><literal>th</literal> suffix</entry>
5744         <entry>lower case ordinal number suffix</entry>
5745         <entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
5746        </row>
5747        <row>
5748         <entry><literal>FX</literal> prefix</entry>
5749         <entry>fixed format global option (see usage notes)</entry>
5750         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5751        </row>
5752        <row>
5753         <entry><literal>TM</literal> prefix</entry>
5754         <entry>translation mode (print localized day and month names based on
5755          <xref linkend="guc-lc-time">)</entry>
5756         <entry><literal>TMMonth</literal></entry>
5757        </row>
5758        <row>
5759         <entry><literal>SP</literal> suffix</entry>
5760         <entry>spell mode (not implemented)</entry>
5761         <entry><literal>DDSP</literal></entry>
5762        </row>
5763       </tbody>
5764      </tgroup>
5765     </table>
5766
5767    <para>
5768     Usage notes for date/time formatting:
5769
5770     <itemizedlist>
5771      <listitem>
5772       <para>
5773        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5774        that would otherwise be added to make the output of a pattern be
5775        fixed-width.  In <productname>PostgreSQL</productname>,
5776        <literal>FM</literal> modifies only the next specification, while in
5777        Oracle <literal>FM</literal> affects all subsequent
5778        specifications, and repeated <literal>FM</literal> modifiers
5779        toggle fill mode on and off.
5780       </para>
5781      </listitem>
5782
5783      <listitem>
5784       <para>
5785        <literal>TM</literal> does not include trailing blanks.
5786        <function>to_timestamp</> and <function>to_date</> ignore
5787        the <literal>TM</literal> modifier.
5788       </para>
5789      </listitem>
5790
5791      <listitem>
5792       <para>
5793        <function>to_timestamp</function> and <function>to_date</function>
5794        skip multiple blank spaces in the input string unless the
5795        <literal>FX</literal> option is used. For example,
5796        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> works, but
5797        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
5798        because <function>to_timestamp</function> expects one space only.
5799        <literal>FX</literal> must be specified as the first item in
5800        the template.
5801       </para>
5802      </listitem>
5803
5804      <listitem>
5805       <para>
5806        <function>to_timestamp</function> and <function>to_date</function>
5807        exist to handle input formats that cannot be converted by
5808        simple casting.  These functions interpret input liberally,
5809        with minimal error checking.  While they produce valid output,
5810        the conversion can yield unexpected results.  For example,
5811        input to these functions is not restricted by normal ranges,
5812        thus <literal>to_date('20096040','YYYYMMDD')</literal> returns
5813        <literal>2014-01-17</literal> rather than causing an error.
5814        Casting does not have this behavior.
5815       </para>
5816      </listitem>
5817
5818      <listitem>
5819       <para>
5820        Ordinary text is allowed in <function>to_char</function>
5821        templates and will be output literally.  You can put a substring
5822        in double quotes to force it to be interpreted as literal text
5823        even if it contains pattern key words.  For example, in
5824        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5825        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5826        will not be.  In <function>to_date</>, <function>to_number</>,
5827        and <function>to_timestamp</>, double-quoted strings skip the number of
5828        input characters contained in the string, e.g. <literal>"XX"</>
5829        skips two input characters.
5830       </para>
5831      </listitem>
5832
5833      <listitem>
5834       <para>
5835        If you want to have a double quote in the output you must
5836        precede it with a backslash, for example <literal>'\"YYYY
5837        Month\"'</literal>. <!-- "" font-lock sanity :-) -->
5838       </para>
5839      </listitem>
5840
5841      <listitem>
5842       <para>
5843        If the year format specification is less than four digits, e.g.
5844        <literal>YYY</>, and the supplied year is less than four digits,
5845        the year will be adjusted to be nearest to the year 2020, e.g.
5846        <literal>95</> becomes 1995.
5847       </para>
5848      </listitem>
5849
5850      <listitem>
5851       <para>
5852        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5853        <type>date</type> has a restriction when processing years with more than 4 digits. You must
5854        use some non-digit character or template after <literal>YYYY</literal>,
5855        otherwise the year is always interpreted as 4 digits. For example
5856        (with the year 20000):
5857        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
5858        interpreted as a 4-digit year; instead use a non-digit
5859        separator after the year, like
5860        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5861        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5862       </para>
5863      </listitem>
5864
5865      <listitem>
5866       <para>
5867        In conversions from string to <type>timestamp</type> or
5868        <type>date</type>, the <literal>CC</literal> (century) field is ignored
5869        if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
5870        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5871        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5872        as the year in the specified century.  If the century is
5873        specified but the year is not, the first year of the century
5874        is assumed.
5875       </para>
5876      </listitem>
5877
5878      <listitem>
5879       <para>
5880        An ISO 8601 week-numbering date (as distinct from a Gregorian date)
5881        can be specified to <function>to_timestamp</function> and
5882        <function>to_date</function> in one of two ways:
5883        <itemizedlist>
5884         <listitem>
5885          <para>
5886           Year, week number, and weekday:  for
5887           example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal>
5888           returns the date <literal>2006-10-19</literal>.
5889           If you omit the weekday it is assumed to be 1 (Monday).
5890          </para>
5891         </listitem>
5892         <listitem>
5893          <para>
5894           Year and day of year:  for example <literal>to_date('2006-291',
5895           'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5896          </para>
5897         </listitem>
5898        </itemizedlist>
5899       </para>
5900       <para>
5901        Attempting to enter a date using a mixture of ISO 8601 week-numbering
5902        fields and Gregorian date fields is nonsensical, and will cause an
5903        error.  In the context of an ISO 8601 week-numbering year, the
5904        concept of a <quote>month</> or <quote>day of month</> has no
5905        meaning.  In the context of a Gregorian year, the ISO week has no
5906        meaning.
5907       </para>
5908       <caution>
5909        <para>
5910         While <function>to_date</function> will reject a mixture of
5911         Gregorian and ISO week-numbering date
5912         fields, <function>to_char</function> will not, since output format
5913         specifications like <literal>YYYY-MM-DD (IYYY-IDDD)</> can be
5914         useful.  But avoid writing something like <literal>IYYY-MM-DD</>;
5915         that would yield surprising results near the start of the year.
5916         (See <xref linkend="functions-datetime-extract"> for more
5917         information.)
5918        </para>
5919       </caution>
5920      </listitem>
5921
5922      <listitem>
5923       <para>
5924        In a conversion from string to <type>timestamp</type>, millisecond
5925        (<literal>MS</literal>) or microsecond (<literal>US</literal>)
5926        values are used as the
5927        seconds digits after the decimal point. For example
5928        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5929        but 300, because the conversion counts it as 12 + 0.3 seconds.
5930        This means for the format <literal>SS:MS</literal>, the input values
5931        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5932        same number of milliseconds. To get three milliseconds, one must use
5933        <literal>12:003</literal>, which the conversion counts as
5934        12 + 0.003 = 12.003 seconds.
5935       </para>
5936
5937       <para>
5938        Here is a more
5939        complex example:
5940        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5941        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5942        1230 microseconds = 2.021230 seconds.
5943       </para>
5944      </listitem>
5945
5946      <listitem>
5947       <para>
5948         <function>to_char(..., 'ID')</function>'s day of the week numbering
5949         matches the <function>extract(isodow from ...)</function> function, but
5950         <function>to_char(..., 'D')</function>'s does not match
5951         <function>extract(dow from ...)</function>'s day numbering.
5952       </para>
5953      </listitem>
5954
5955      <listitem>
5956       <para>
5957         <function>to_char(interval)</function> formats <literal>HH</> and
5958         <literal>HH12</> as shown on a 12-hour clock, i.e. zero hours
5959         and 36 hours output as <literal>12</>, while <literal>HH24</>
5960         outputs the full hour value, which can exceed 23 for intervals.
5961       </para>
5962      </listitem>
5963
5964     </itemizedlist>
5965    </para>
5966
5967   <para>
5968    <xref linkend="functions-formatting-numeric-table"> shows the
5969    template patterns available for formatting numeric values.
5970   </para>
5971
5972     <table id="functions-formatting-numeric-table">
5973      <title>Template Patterns for Numeric Formatting</title>
5974      <tgroup cols="2">
5975       <thead>
5976        <row>
5977         <entry>Pattern</entry>
5978         <entry>Description</entry>
5979        </row>
5980       </thead>
5981       <tbody>
5982        <row>
5983         <entry><literal>9</literal></entry>
5984         <entry>value with the specified number of digits</entry>
5985        </row>
5986        <row>
5987         <entry><literal>0</literal></entry>
5988         <entry>value with leading zeros</entry>
5989        </row>
5990        <row>
5991         <entry><literal>.</literal> (period)</entry>
5992         <entry>decimal point</entry>
5993        </row>
5994        <row>
5995         <entry><literal>,</literal> (comma)</entry>
5996         <entry>group (thousand) separator</entry>
5997        </row>
5998        <row>
5999         <entry><literal>PR</literal></entry>
6000         <entry>negative value in angle brackets</entry>
6001        </row>
6002        <row>
6003         <entry><literal>S</literal></entry>
6004         <entry>sign anchored to number (uses locale)</entry>
6005        </row>
6006        <row>
6007         <entry><literal>L</literal></entry>
6008         <entry>currency symbol (uses locale)</entry>
6009        </row>
6010        <row>
6011         <entry><literal>D</literal></entry>
6012         <entry>decimal point (uses locale)</entry>
6013        </row>
6014        <row>
6015         <entry><literal>G</literal></entry>
6016         <entry>group separator (uses locale)</entry>
6017        </row>
6018        <row>
6019         <entry><literal>MI</literal></entry>
6020         <entry>minus sign in specified position (if number &lt; 0)</entry>
6021        </row>
6022        <row>
6023         <entry><literal>PL</literal></entry>
6024         <entry>plus sign in specified position (if number &gt; 0)</entry>
6025        </row>
6026        <row>
6027         <entry><literal>SG</literal></entry>
6028         <entry>plus/minus sign in specified position</entry>
6029        </row>
6030        <row>
6031         <entry><literal>RN</literal></entry>
6032         <entry>Roman numeral (input between 1 and 3999)</entry>
6033        </row>
6034        <row>
6035         <entry><literal>TH</literal> or <literal>th</literal></entry>
6036         <entry>ordinal number suffix</entry>
6037        </row>
6038        <row>
6039         <entry><literal>V</literal></entry>
6040         <entry>shift specified number of digits (see notes)</entry>
6041        </row>
6042        <row>
6043         <entry><literal>EEEE</literal></entry>
6044         <entry>exponent for scientific notation</entry>
6045        </row>
6046       </tbody>
6047      </tgroup>
6048     </table>
6049
6050    <para>
6051     Usage notes for numeric formatting:
6052
6053     <itemizedlist>
6054      <listitem>
6055       <para>
6056        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
6057        <literal>MI</literal> is not anchored to
6058        the number; for example,
6059        <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
6060        but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
6061        The Oracle implementation does not allow the use of
6062        <literal>MI</literal> before <literal>9</literal>, but rather
6063        requires that <literal>9</literal> precede
6064        <literal>MI</literal>.
6065       </para>
6066      </listitem>
6067
6068      <listitem>
6069       <para>
6070        <literal>9</literal> results in a value with the same number of
6071        digits as there are <literal>9</literal>s. If a digit is
6072        not available it outputs a space.
6073       </para>
6074      </listitem>
6075
6076      <listitem>
6077       <para>
6078        <literal>TH</literal> does not convert values less than zero
6079        and does not convert fractional numbers.
6080       </para>
6081      </listitem>
6082
6083      <listitem>
6084       <para>
6085        <literal>PL</literal>, <literal>SG</literal>, and
6086        <literal>TH</literal> are <productname>PostgreSQL</productname>
6087        extensions.
6088       </para>
6089      </listitem>
6090
6091      <listitem>
6092       <para>
6093        <literal>V</literal> effectively
6094        multiplies the input values by
6095        <literal>10^<replaceable>n</replaceable></literal>, where
6096        <replaceable>n</replaceable> is the number of digits following
6097        <literal>V</literal>.
6098        <function>to_char</function> does not support the use of
6099        <literal>V</literal> combined with a decimal point
6100        (e.g., <literal>99.9V99</literal> is not allowed).
6101       </para>
6102      </listitem>
6103
6104      <listitem>
6105       <para>
6106        <literal>EEEE</literal> (scientific notation) cannot be used in
6107        combination with any of the other formatting patterns or
6108        modifiers other than digit and decimal point patterns, and must be at the end of the format string
6109        (e.g., <literal>9.99EEEE</literal> is a valid pattern).
6110       </para>
6111      </listitem>
6112     </itemizedlist>
6113    </para>
6114
6115    <para>
6116     Certain modifiers can be applied to any template pattern to alter its
6117     behavior.  For example, <literal>FM9999</literal>
6118     is the <literal>9999</literal> pattern with the
6119     <literal>FM</literal> modifier.
6120     <xref linkend="functions-formatting-numericmod-table"> shows the
6121     modifier patterns for numeric formatting.
6122    </para>
6123
6124     <table id="functions-formatting-numericmod-table">
6125      <title>Template Pattern Modifiers for Numeric Formatting</title>
6126      <tgroup cols="3">
6127       <thead>
6128        <row>
6129         <entry>Modifier</entry>
6130         <entry>Description</entry>
6131         <entry>Example</entry>
6132        </row>
6133       </thead>
6134       <tbody>
6135        <row>
6136         <entry><literal>FM</literal> prefix</entry>
6137         <entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
6138         <entry><literal>FM9999</literal></entry>
6139        </row>
6140        <row>
6141         <entry><literal>TH</literal> suffix</entry>
6142         <entry>upper case ordinal number suffix</entry>
6143         <entry><literal>999TH</literal></entry>
6144        </row>
6145        <row>
6146         <entry><literal>th</literal> suffix</entry>
6147         <entry>lower case ordinal number suffix</entry>
6148         <entry><literal>999th</literal></entry>
6149        </row>
6150       </tbody>
6151      </tgroup>
6152     </table>
6153
6154   <para>
6155    <xref linkend="functions-formatting-examples-table"> shows some
6156    examples of the use of the <function>to_char</function> function.
6157   </para>
6158
6159     <table id="functions-formatting-examples-table">
6160      <title><function>to_char</function> Examples</title>
6161      <tgroup cols="2">
6162       <thead>
6163        <row>
6164         <entry>Expression</entry>
6165         <entry>Result</entry>
6166        </row>
6167       </thead>
6168       <tbody>
6169        <row>
6170         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
6171         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
6172        </row>
6173        <row>
6174         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
6175         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
6176        </row>
6177        <row>
6178         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
6179         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
6180        </row>
6181        <row>
6182         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
6183         <entry><literal>'-.1'</literal></entry>
6184        </row>
6185        <row>
6186         <entry><literal>to_char(0.1, '0.9')</literal></entry>
6187         <entry><literal>'&nbsp;0.1'</literal></entry>
6188        </row>
6189        <row>
6190         <entry><literal>to_char(12, '9990999.9')</literal></entry>
6191         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
6192        </row>
6193        <row>
6194         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
6195         <entry><literal>'0012.'</literal></entry>
6196        </row>
6197        <row>
6198         <entry><literal>to_char(485, '999')</literal></entry>
6199         <entry><literal>'&nbsp;485'</literal></entry>
6200        </row>
6201        <row>
6202         <entry><literal>to_char(-485, '999')</literal></entry>
6203         <entry><literal>'-485'</literal></entry>
6204        </row>
6205        <row>
6206         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
6207         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
6208        </row>
6209        <row>
6210         <entry><literal>to_char(1485, '9,999')</literal></entry>
6211         <entry><literal>'&nbsp;1,485'</literal></entry>
6212        </row>
6213        <row>
6214         <entry><literal>to_char(1485, '9G999')</literal></entry>
6215         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
6216        </row>
6217        <row>
6218         <entry><literal>to_char(148.5, '999.999')</literal></entry>
6219         <entry><literal>'&nbsp;148.500'</literal></entry>
6220        </row>
6221        <row>
6222         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
6223         <entry><literal>'148.5'</literal></entry>
6224        </row>
6225        <row>
6226         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
6227         <entry><literal>'148.500'</literal></entry>
6228        </row>
6229        <row>
6230         <entry><literal>to_char(148.5, '999D999')</literal></entry>
6231         <entry><literal>'&nbsp;148,500'</literal></entry>
6232        </row>
6233        <row>
6234         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
6235         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
6236        </row>
6237        <row>
6238         <entry><literal>to_char(-485, '999S')</literal></entry>
6239         <entry><literal>'485-'</literal></entry>
6240        </row>
6241        <row>
6242         <entry><literal>to_char(-485, '999MI')</literal></entry>
6243         <entry><literal>'485-'</literal></entry>
6244        </row>
6245        <row>
6246         <entry><literal>to_char(485, '999MI')</literal></entry>
6247         <entry><literal>'485&nbsp;'</literal></entry>
6248        </row>
6249        <row>
6250         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
6251         <entry><literal>'485'</literal></entry>
6252        </row>
6253        <row>
6254         <entry><literal>to_char(485, 'PL999')</literal></entry>
6255         <entry><literal>'+485'</literal></entry>
6256        </row>
6257        <row>
6258         <entry><literal>to_char(485, 'SG999')</literal></entry>
6259         <entry><literal>'+485'</literal></entry>
6260        </row>
6261        <row>
6262         <entry><literal>to_char(-485, 'SG999')</literal></entry>
6263         <entry><literal>'-485'</literal></entry>
6264        </row>
6265        <row>
6266         <entry><literal>to_char(-485, '9SG99')</literal></entry>
6267         <entry><literal>'4-85'</literal></entry>
6268        </row>
6269        <row>
6270         <entry><literal>to_char(-485, '999PR')</literal></entry>
6271         <entry><literal>'&lt;485&gt;'</literal></entry>
6272        </row>
6273        <row>
6274         <entry><literal>to_char(485, 'L999')</literal></entry>
6275         <entry><literal>'DM&nbsp;485</literal></entry>
6276        </row>
6277        <row>
6278         <entry><literal>to_char(485, 'RN')</literal></entry>
6279         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
6280        </row>
6281        <row>
6282         <entry><literal>to_char(485, 'FMRN')</literal></entry>
6283         <entry><literal>'CDLXXXV'</literal></entry>
6284        </row>
6285        <row>
6286         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
6287         <entry><literal>'V'</literal></entry>
6288        </row>
6289        <row>
6290         <entry><literal>to_char(482, '999th')</literal></entry>
6291         <entry><literal>'&nbsp;482nd'</literal></entry>
6292        </row>
6293        <row>
6294         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
6295         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
6296        </row>
6297        <row>
6298         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
6299         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
6300        </row>
6301        <row>
6302         <entry><literal>to_char(12, '99V999')</literal></entry>
6303         <entry><literal>'&nbsp;12000'</literal></entry>
6304        </row>
6305        <row>
6306         <entry><literal>to_char(12.4, '99V999')</literal></entry>
6307         <entry><literal>'&nbsp;12400'</literal></entry>
6308        </row>
6309        <row>
6310         <entry><literal>to_char(12.45, '99V9')</literal></entry>
6311         <entry><literal>'&nbsp;125'</literal></entry>
6312        </row>
6313        <row>
6314         <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
6315         <entry><literal>' 4.86e-04'</literal></entry>
6316        </row>
6317       </tbody>
6318      </tgroup>
6319     </table>
6320
6321   </sect1>
6322
6323
6324   <sect1 id="functions-datetime">
6325    <title>Date/Time Functions and Operators</title>
6326
6327   <para>
6328    <xref linkend="functions-datetime-table"> shows the available
6329    functions for date/time value processing, with details appearing in
6330    the following subsections.  <xref
6331    linkend="operators-datetime-table"> illustrates the behaviors of
6332    the basic arithmetic operators (<literal>+</literal>,
6333    <literal>*</literal>, etc.).  For formatting functions, refer to
6334    <xref linkend="functions-formatting">.  You should be familiar with
6335    the background information on date/time data types from <xref
6336    linkend="datatype-datetime">.
6337   </para>
6338
6339   <para>
6340    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
6341    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
6342    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
6343    For brevity, these variants are not shown separately.  Also, the
6344    <literal>+</> and <literal>*</> operators come in commutative pairs (for
6345    example both date + integer and integer + date); we show only one of each
6346    such pair.
6347   </para>
6348
6349     <table id="operators-datetime-table">
6350      <title>Date/Time Operators</title>
6351
6352      <tgroup cols="3">
6353       <thead>
6354        <row>
6355         <entry>Operator</entry>
6356         <entry>Example</entry>
6357         <entry>Result</entry>
6358        </row>
6359       </thead>
6360
6361       <tbody>
6362        <row>
6363         <entry> <literal>+</literal> </entry>
6364         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
6365         <entry><literal>date '2001-10-05'</literal></entry>
6366        </row>
6367
6368        <row>
6369         <entry> <literal>+</literal> </entry>
6370         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
6371         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
6372        </row>
6373
6374        <row>
6375         <entry> <literal>+</literal> </entry>
6376         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
6377         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
6378        </row>
6379
6380        <row>
6381         <entry> <literal>+</literal> </entry>
6382         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
6383         <entry><literal>interval '1 day 01:00:00'</literal></entry>
6384        </row>
6385
6386        <row>
6387         <entry> <literal>+</literal> </entry>
6388         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
6389         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
6390        </row>
6391
6392        <row>
6393         <entry> <literal>+</literal> </entry>
6394         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
6395         <entry><literal>time '04:00:00'</literal></entry>
6396        </row>
6397
6398        <row>
6399         <entry> <literal>-</literal> </entry>
6400         <entry><literal>- interval '23 hours'</literal></entry>
6401         <entry><literal>interval '-23:00:00'</literal></entry>
6402        </row>
6403
6404        <row>
6405         <entry> <literal>-</literal> </entry>
6406         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
6407         <entry><literal>integer '3'</literal> (days)</entry>
6408        </row>
6409
6410        <row>
6411         <entry> <literal>-</literal> </entry>
6412         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
6413         <entry><literal>date '2001-09-24'</literal></entry>
6414        </row>
6415
6416        <row>
6417         <entry> <literal>-</literal> </entry>
6418         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
6419         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
6420        </row>
6421
6422        <row>
6423         <entry> <literal>-</literal> </entry>
6424         <entry><literal>time '05:00' - time '03:00'</literal></entry>
6425         <entry><literal>interval '02:00:00'</literal></entry>
6426        </row>
6427
6428        <row>
6429         <entry> <literal>-</literal> </entry>
6430         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
6431         <entry><literal>time '03:00:00'</literal></entry>
6432        </row>
6433
6434        <row>
6435         <entry> <literal>-</literal> </entry>
6436         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
6437         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
6438        </row>
6439
6440        <row>
6441         <entry> <literal>-</literal> </entry>
6442         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
6443         <entry><literal>interval '1 day -01:00:00'</literal></entry>
6444        </row>
6445
6446        <row>
6447         <entry> <literal>-</literal> </entry>
6448         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
6449         <entry><literal>interval '1 day 15:00:00'</literal></entry>
6450        </row>
6451
6452        <row>
6453         <entry> <literal>*</literal> </entry>
6454         <entry><literal>900 * interval '1 second'</literal></entry>
6455         <entry><literal>interval '00:15:00'</literal></entry>
6456        </row>
6457
6458        <row>
6459         <entry> <literal>*</literal> </entry>
6460         <entry><literal>21 * interval '1 day'</literal></entry>
6461         <entry><literal>interval '21 days'</literal></entry>
6462        </row>
6463
6464        <row>
6465         <entry> <literal>*</literal> </entry>
6466         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
6467         <entry><literal>interval '03:30:00'</literal></entry>
6468        </row>
6469
6470        <row>
6471         <entry> <literal>/</literal> </entry>
6472         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
6473         <entry><literal>interval '00:40:00'</literal></entry>
6474        </row>
6475       </tbody>
6476      </tgroup>
6477     </table>
6478
6479     <table id="functions-datetime-table">
6480      <title>Date/Time Functions</title>
6481      <tgroup cols="5">
6482       <thead>
6483        <row>
6484         <entry>Function</entry>
6485         <entry>Return Type</entry>
6486         <entry>Description</entry>
6487         <entry>Example</entry>
6488         <entry>Result</entry>
6489        </row>
6490       </thead>
6491
6492       <tbody>
6493        <row>
6494         <entry>
6495          <indexterm>
6496           <primary>age</primary>
6497          </indexterm>
6498          <literal><function>age(<type>timestamp</type>, <type>timestamp</type>)</function></literal>
6499         </entry>
6500         <entry><type>interval</type></entry>
6501         <entry>Subtract arguments, producing a <quote>symbolic</> result that
6502         uses years and months, rather than just days</entry>
6503         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
6504         <entry><literal>43 years 9 mons 27 days</literal></entry>
6505        </row>
6506
6507        <row>
6508         <entry><literal><function>age(<type>timestamp</type>)</function></literal></entry>
6509         <entry><type>interval</type></entry>
6510         <entry>Subtract from <function>current_date</function> (at midnight)</entry>
6511         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
6512         <entry><literal>43 years 8 mons 3 days</literal></entry>
6513        </row>
6514
6515        <row>
6516         <entry>
6517          <indexterm>
6518           <primary>clock_timestamp</primary>
6519          </indexterm>
6520          <literal><function>clock_timestamp()</function></literal>
6521         </entry>
6522         <entry><type>timestamp with time zone</type></entry>
6523         <entry>Current date and time (changes during statement execution);
6524          see <xref linkend="functions-datetime-current">
6525         </entry>
6526         <entry></entry>
6527         <entry></entry>
6528        </row>
6529
6530        <row>
6531         <entry>
6532          <indexterm>
6533           <primary>current_date</primary>
6534          </indexterm>
6535          <literal><function>current_date</function></literal>
6536         </entry>
6537         <entry><type>date</type></entry>
6538         <entry>Current date;
6539          see <xref linkend="functions-datetime-current">
6540         </entry>
6541         <entry></entry>
6542         <entry></entry>
6543        </row>
6544
6545        <row>
6546         <entry>
6547          <indexterm>
6548           <primary>current_time</primary>
6549          </indexterm>
6550          <literal><function>current_time</function></literal>
6551         </entry>
6552         <entry><type>time with time zone</type></entry>
6553         <entry>Current time of day;
6554          see <xref linkend="functions-datetime-current">
6555         </entry>
6556         <entry></entry>
6557         <entry></entry>
6558        </row>
6559
6560        <row>
6561         <entry>
6562          <indexterm>
6563           <primary>current_timestamp</primary>
6564          </indexterm>
6565          <literal><function>current_timestamp</function></literal>
6566         </entry>
6567         <entry><type>timestamp with time zone</type></entry>
6568         <entry>Current date and time (start of current transaction);
6569          see <xref linkend="functions-datetime-current">
6570         </entry>
6571         <entry></entry>
6572         <entry></entry>
6573        </row>
6574
6575        <row>
6576         <entry>
6577          <indexterm>
6578           <primary>date_part</primary>
6579          </indexterm>
6580          <literal><function>date_part(<type>text</type>, <type>timestamp</type>)</function></literal>
6581         </entry>
6582         <entry><type>double precision</type></entry>
6583         <entry>Get subfield (equivalent to <function>extract</function>);
6584          see <xref linkend="functions-datetime-extract">
6585         </entry>
6586         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6587         <entry><literal>20</literal></entry>
6588        </row>
6589
6590        <row>
6591         <entry><literal><function>date_part(<type>text</type>, <type>interval</type>)</function></literal></entry>
6592         <entry><type>double precision</type></entry>
6593         <entry>Get subfield (equivalent to
6594          <function>extract</function>); see <xref linkend="functions-datetime-extract">
6595         </entry>
6596         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
6597         <entry><literal>3</literal></entry>
6598        </row>
6599
6600        <row>
6601         <entry>
6602          <indexterm>
6603           <primary>date_trunc</primary>
6604          </indexterm>
6605          <literal><function>date_trunc(<type>text</type>, <type>timestamp</type>)</function></literal>
6606         </entry>
6607         <entry><type>timestamp</type></entry>
6608         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
6609         </entry>
6610         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6611         <entry><literal>2001-02-16 20:00:00</literal></entry>
6612        </row>
6613
6614        <row>
6615         <entry><literal><function>date_trunc(<type>text</type>, <type>interval</type>)</function></literal></entry>
6616         <entry><type>interval</type></entry>
6617         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
6618         </entry>
6619         <entry><literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal></entry>
6620         <entry><literal>2 days 03:00:00</literal></entry>
6621        </row>
6622
6623        <row>
6624         <entry>
6625          <indexterm>
6626           <primary>extract</primary>
6627          </indexterm>
6628          <literal><function>extract</function>(<parameter>field</parameter> from
6629          <type>timestamp</type>)</literal>
6630         </entry>
6631         <entry><type>double precision</type></entry>
6632         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6633         </entry>
6634         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
6635         <entry><literal>20</literal></entry>
6636        </row>
6637
6638        <row>
6639         <entry><literal><function>extract</function>(<parameter>field</parameter> from
6640          <type>interval</type>)</literal></entry>
6641         <entry><type>double precision</type></entry>
6642         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6643         </entry>
6644         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
6645         <entry><literal>3</literal></entry>
6646        </row>
6647
6648        <row>
6649         <entry>
6650          <indexterm>
6651           <primary>isfinite</primary>
6652          </indexterm>
6653          <literal><function>isfinite(<type>date</type>)</function></literal>
6654         </entry>
6655         <entry><type>boolean</type></entry>
6656         <entry>Test for finite date (not +/-infinity)</entry>
6657         <entry><literal>isfinite(date '2001-02-16')</literal></entry>
6658         <entry><literal>true</literal></entry>
6659        </row>
6660
6661        <row>
6662         <entry><literal><function>isfinite(<type>timestamp</type>)</function></literal></entry>
6663         <entry><type>boolean</type></entry>
6664         <entry>Test for finite time stamp (not +/-infinity)</entry>
6665         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
6666         <entry><literal>true</literal></entry>
6667        </row>
6668
6669        <row>
6670         <entry><literal><function>isfinite(<type>interval</type>)</function></literal></entry>
6671         <entry><type>boolean</type></entry>
6672         <entry>Test for finite interval</entry>
6673         <entry><literal>isfinite(interval '4 hours')</literal></entry>
6674         <entry><literal>true</literal></entry>
6675        </row>
6676
6677        <row>
6678         <entry>
6679          <indexterm>
6680           <primary>justify_days</primary>
6681          </indexterm>
6682          <literal><function>justify_days(<type>interval</type>)</function></literal>
6683         </entry>
6684         <entry><type>interval</type></entry>
6685         <entry>Adjust interval so 30-day time periods are represented as months</entry>
6686         <entry><literal>justify_days(interval '35 days')</literal></entry>
6687         <entry><literal>1 mon 5 days</literal></entry>
6688        </row>
6689
6690        <row>
6691         <entry>
6692          <indexterm>
6693           <primary>justify_hours</primary>
6694          </indexterm>
6695          <literal><function>justify_hours(<type>interval</type>)</function></literal>
6696         </entry>
6697         <entry><type>interval</type></entry>
6698         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
6699         <entry><literal>justify_hours(interval '27 hours')</literal></entry>
6700         <entry><literal>1 day 03:00:00</literal></entry>
6701        </row>
6702
6703        <row>
6704         <entry>
6705          <indexterm>
6706           <primary>justify_interval</primary>
6707          </indexterm>
6708          <literal><function>justify_interval(<type>interval</type>)</function></literal>
6709         </entry>
6710         <entry><type>interval</type></entry>
6711         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
6712         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
6713         <entry><literal>29 days 23:00:00</literal></entry>
6714        </row>
6715
6716        <row>
6717         <entry>
6718          <indexterm>
6719           <primary>localtime</primary>
6720          </indexterm>
6721          <literal><function>localtime</function></literal>
6722         </entry>
6723         <entry><type>time</type></entry>
6724         <entry>Current time of day;
6725          see <xref linkend="functions-datetime-current">
6726         </entry>
6727         <entry></entry>
6728         <entry></entry>
6729        </row>
6730
6731        <row>
6732         <entry>
6733          <indexterm>
6734           <primary>localtimestamp</primary>
6735          </indexterm>
6736          <literal><function>localtimestamp</function></literal>
6737         </entry>
6738         <entry><type>timestamp</type></entry>
6739         <entry>Current date and time (start of current transaction);
6740          see <xref linkend="functions-datetime-current">
6741         </entry>
6742         <entry></entry>
6743         <entry></entry>
6744        </row>
6745
6746        <row>
6747         <entry>
6748          <indexterm>
6749           <primary>make_date</primary>
6750          </indexterm>
6751          <literal>
6752             <function>
6753              make_date(<parameter>year</parameter> <type>int</type>,
6754              <parameter>month</parameter> <type>int</type>,
6755              <parameter>day</parameter> <type>int</type>)
6756             </function>
6757          </literal>
6758         </entry>
6759         <entry><type>date</type></entry>
6760         <entry>
6761          Create date from year, month and day fields
6762         </entry>
6763         <entry><literal>make_date(2013, 7, 15)</literal></entry>
6764         <entry><literal>2013-07-15</literal></entry>
6765        </row>
6766
6767        <row>
6768         <entry>
6769          <indexterm>
6770           <primary>make_interval</primary>
6771          </indexterm>
6772          <literal>
6773           <function>
6774            make_interval(<parameter>years</parameter> <type>int</type> DEFAULT 0,
6775            <parameter>months</parameter> <type>int</type> DEFAULT 0,
6776            <parameter>weeks</parameter> <type>int</type> DEFAULT 0,
6777            <parameter>days</parameter> <type>int</type> DEFAULT 0,
6778            <parameter>hours</parameter> <type>int</type> DEFAULT 0,
6779            <parameter>mins</parameter> <type>int</type> DEFAULT 0,
6780            <parameter>secs</parameter> <type>double precision</type> DEFAULT 0.0)
6781           </function>
6782          </literal>
6783         </entry>
6784         <entry><type>interval</type></entry>
6785         <entry>
6786          Create interval from years, months, weeks, days, hours, minutes and
6787          seconds fields
6788         </entry>
6789         <entry><literal>make_interval(days => 10)</literal></entry>
6790         <entry><literal>10 days</literal></entry>
6791        </row>
6792
6793        <row>
6794         <entry>
6795          <indexterm>
6796           <primary>make_time</primary>
6797          </indexterm>
6798          <literal>
6799           <function>
6800            make_time(<parameter>hour</parameter> <type>int</type>,
6801            <parameter>min</parameter> <type>int</type>,
6802            <parameter>sec</parameter> <type>double precision</type>)
6803           </function>
6804          </literal>
6805         </entry>
6806         <entry><type>time</type></entry>
6807         <entry>
6808          Create time from hour, minute and seconds fields
6809         </entry>
6810         <entry><literal>make_time(8, 15, 23.5)</literal></entry>
6811         <entry><literal>08:15:23.5</literal></entry>
6812        </row>
6813
6814        <row>
6815         <entry>
6816          <indexterm>
6817           <primary>make_timestamp</primary>
6818          </indexterm>
6819          <literal>
6820           <function>
6821            make_timestamp(<parameter>year</parameter> <type>int</type>,
6822            <parameter>month</parameter> <type>int</type>,
6823            <parameter>day</parameter> <type>int</type>,
6824            <parameter>hour</parameter> <type>int</type>,
6825            <parameter>min</parameter> <type>int</type>,
6826            <parameter>sec</parameter> <type>double precision</type>)
6827           </function>
6828          </literal>
6829         </entry>
6830         <entry><type>timestamp</type></entry>
6831         <entry>
6832          Create timestamp from year, month, day, hour, minute and seconds fields
6833         </entry>
6834         <entry><literal>make_timestamp(2013, 7, 15, 8, 15, 23.5)</literal></entry>
6835         <entry><literal>2013-07-15 08:15:23.5</literal></entry>
6836        </row>
6837
6838        <row>
6839         <entry>
6840          <indexterm>
6841           <primary>make_timestamptz</primary>
6842          </indexterm>
6843          <literal>
6844           <function>
6845            make_timestamptz(<parameter>year</parameter> <type>int</type>,
6846            <parameter>month</parameter> <type>int</type>,
6847            <parameter>day</parameter> <type>int</type>,
6848            <parameter>hour</parameter> <type>int</type>,
6849            <parameter>min</parameter> <type>int</type>,
6850            <parameter>sec</parameter> <type>double precision</type>,
6851            <optional> <parameter>timezone</parameter> <type>text</type> </optional>)
6852           </function>
6853          </literal>
6854         </entry>
6855         <entry><type>timestamp with time zone</type></entry>
6856         <entry>
6857          Create timestamp with time zone from year, month, day, hour, minute
6858          and seconds fields. When <parameter>timezone</parameter> is not specified,
6859          then current time zone is used.
6860         </entry>
6861         <entry><literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5)</literal></entry>
6862         <entry><literal>2013-07-15 08:15:23.5+01</literal></entry>
6863        </row>
6864
6865        <row>
6866         <entry>
6867          <indexterm>
6868           <primary>now</primary>
6869          </indexterm>
6870          <literal><function>now()</function></literal>
6871         </entry>
6872         <entry><type>timestamp with time zone</type></entry>
6873         <entry>Current date and time (start of current transaction);
6874          see <xref linkend="functions-datetime-current">
6875         </entry>
6876         <entry></entry>
6877         <entry></entry>
6878        </row>
6879
6880        <row>
6881         <entry>
6882          <indexterm>
6883           <primary>statement_timestamp</primary>
6884          </indexterm>
6885          <literal><function>statement_timestamp()</function></literal>
6886         </entry>
6887         <entry><type>timestamp with time zone</type></entry>
6888         <entry>Current date and time (start of current statement);
6889          see <xref linkend="functions-datetime-current">
6890         </entry>
6891         <entry></entry>
6892         <entry></entry>
6893        </row>
6894
6895        <row>
6896         <entry>
6897          <indexterm>
6898           <primary>timeofday</primary>
6899          </indexterm>
6900          <literal><function>timeofday()</function></literal>
6901         </entry>
6902         <entry><type>text</type></entry>
6903         <entry>Current date and time
6904          (like <function>clock_timestamp</>, but as a <type>text</> string);
6905          see <xref linkend="functions-datetime-current">
6906         </entry>
6907         <entry></entry>
6908         <entry></entry>
6909        </row>
6910
6911        <row>
6912         <entry>
6913          <indexterm>
6914           <primary>transaction_timestamp</primary>
6915          </indexterm>
6916          <literal><function>transaction_timestamp()</function></literal>
6917         </entry>
6918         <entry><type>timestamp with time zone</type></entry>
6919         <entry>Current date and time (start of current transaction);
6920          see <xref linkend="functions-datetime-current">
6921         </entry>
6922         <entry></entry>
6923         <entry></entry>
6924        </row>
6925       </tbody>
6926      </tgroup>
6927     </table>
6928
6929    <para>
6930     <indexterm>
6931       <primary>OVERLAPS</primary>
6932     </indexterm>
6933     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6934     supported:
6935 <synopsis>
6936 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6937 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6938 </synopsis>
6939     This expression yields true when two time periods (defined by their
6940     endpoints) overlap, false when they do not overlap.  The endpoints
6941     can be specified as pairs of dates, times, or time stamps; or as
6942     a date, time, or time stamp followed by an interval.  When a pair
6943     of values is provided, either the start or the end can be written
6944     first; <literal>OVERLAPS</> automatically takes the earlier value
6945     of the pair as the start.  Each time period is considered to
6946     represent the half-open interval <replaceable>start</> <literal>&lt;=</>
6947     <replaceable>time</> <literal>&lt;</> <replaceable>end</>, unless
6948     <replaceable>start</> and <replaceable>end</> are equal in which case it
6949     represents that single time instant.  This means for instance that two
6950     time periods with only an endpoint in common do not overlap.
6951    </para>
6952
6953 <screen>
6954 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6955        (DATE '2001-10-30', DATE '2002-10-30');
6956 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6957 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6958        (DATE '2001-10-30', DATE '2002-10-30');
6959 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6960 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
6961        (DATE '2001-10-30', DATE '2001-10-31');
6962 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6963 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
6964        (DATE '2001-10-30', DATE '2001-10-31');
6965 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6966 </screen>
6967
6968   <para>
6969    When adding an <type>interval</type> value to (or subtracting an
6970    <type>interval</type> value from) a <type>timestamp with time zone</type>
6971    value, the days component advances or decrements the date of the
6972    <type>timestamp with time zone</type> by the indicated number of days.
6973    Across daylight saving time changes (when the session time zone is set to a
6974    time zone that recognizes DST), this means <literal>interval '1 day'</literal>
6975    does not necessarily equal <literal>interval '24 hours'</literal>.
6976    For example, with the session time zone set to <literal>CST7CDT</literal>,
6977    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day'</literal>
6978    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>,
6979    while adding <literal>interval '24 hours'</literal> to the same initial
6980    <type>timestamp with time zone</type> produces
6981    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6982    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone
6983    <literal>CST7CDT</literal>.
6984   </para>
6985
6986   <para>
6987    Note there can be ambiguity in the <literal>months</> field returned by
6988    <function>age</> because different months have different numbers of
6989    days.  <productname>PostgreSQL</>'s approach uses the month from the
6990    earlier of the two dates when calculating partial months.  For example,
6991    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6992    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6993    days</> because May has 31 days, while April has only 30.
6994   </para>
6995
6996   <para>
6997    Subtraction of dates and timestamps can also be complex.  One conceptually
6998    simple way to perform subtraction is to convert each value to a number
6999    of seconds using <literal>EXTRACT(EPOCH FROM ...)</>, then subtract the
7000    results; this produces the
7001    number of <emphasis>seconds</> between the two values.  This will adjust
7002    for the number of days in each month, timezone changes, and daylight
7003    saving time adjustments.  Subtraction of date or timestamp
7004    values with the <quote><literal>-</></quote> operator
7005    returns the number of days (24-hours) and hours/minutes/seconds
7006    between the values, making the same adjustments.  The <function>age</>
7007    function returns years, months, days, and hours/minutes/seconds,
7008    performing field-by-field subtraction and then adjusting for negative
7009    field values.  The following queries illustrate the differences in these
7010    approaches.  The sample results were produced with <literal>timezone
7011    = 'US/Eastern'</>; there is a daylight saving time change between the
7012    two dates used:
7013   </para>
7014
7015 <screen>
7016 SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
7017        EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
7018 <lineannotation>Result: </lineannotation><computeroutput>10537200</computeroutput>
7019 SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
7020         EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
7021         / 60 / 60 / 24;
7022 <lineannotation>Result: </lineannotation><computeroutput>121.958333333333</computeroutput>
7023 SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
7024 <lineannotation>Result: </lineannotation><computeroutput>121 days 23:00:00</computeroutput>
7025 SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00');
7026 <lineannotation>Result: </lineannotation><computeroutput>4 mons</computeroutput>
7027 </screen>
7028
7029   <sect2 id="functions-datetime-extract">
7030    <title><function>EXTRACT</function>, <function>date_part</function></title>
7031
7032    <indexterm>
7033     <primary>date_part</primary>
7034    </indexterm>
7035    <indexterm>
7036     <primary>extract</primary>
7037    </indexterm>
7038
7039 <synopsis>
7040 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
7041 </synopsis>
7042
7043    <para>
7044     The <function>extract</function> function retrieves subfields
7045     such as year or hour from date/time values.
7046     <replaceable>source</replaceable> must be a value expression of
7047     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
7048     (Expressions of type <type>date</type> are
7049     cast to <type>timestamp</type> and can therefore be used as
7050     well.)  <replaceable>field</replaceable> is an identifier or
7051     string that selects what field to extract from the source value.
7052     The <function>extract</function> function returns values of type
7053     <type>double precision</type>.
7054     The following are valid field names:
7055
7056     <!-- alphabetical -->
7057     <variablelist>
7058      <varlistentry>
7059       <term><literal>century</literal></term>
7060       <listitem>
7061        <para>
7062         The century
7063        </para>
7064
7065 <screen>
7066 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
7067 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
7068 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
7069 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
7070 </screen>
7071
7072        <para>
7073         The first century starts at 0001-01-01 00:00:00 AD, although
7074         they did not know it at the time. This definition applies to all
7075         Gregorian calendar countries. There is no century number 0,
7076         you go from -1 century to 1 century.
7077
7078         If you disagree with this, please write your complaint to:
7079         Pope, Cathedral Saint-Peter of Roma, Vatican.
7080        </para>
7081       </listitem>
7082      </varlistentry>
7083
7084      <varlistentry>
7085       <term><literal>day</literal></term>
7086       <listitem>
7087        <para>
7088         For <type>timestamp</type> values, the day (of the month) field
7089         (1 - 31) ; for <type>interval</type> values, the number of days
7090        </para>
7091
7092 <screen>
7093 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
7094 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
7095
7096 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
7097 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
7098 </screen>
7099
7100
7101
7102       </listitem>
7103      </varlistentry>
7104
7105      <varlistentry>
7106       <term><literal>decade</literal></term>
7107       <listitem>
7108        <para>
7109         The year field divided by 10
7110        </para>
7111
7112 <screen>
7113 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
7114 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
7115 </screen>
7116       </listitem>
7117      </varlistentry>
7118
7119      <varlistentry>
7120       <term><literal>dow</literal></term>
7121       <listitem>
7122        <para>
7123         The day of the week as Sunday (<literal>0</>) to
7124         Saturday (<literal>6</>)
7125        </para>
7126
7127 <screen>
7128 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
7129 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
7130 </screen>
7131        <para>
7132         Note that <function>extract</function>'s day of the week numbering
7133         differs from that of the <function>to_char(...,
7134         'D')</function> function.
7135        </para>
7136
7137       </listitem>
7138      </varlistentry>
7139
7140      <varlistentry>
7141       <term><literal>doy</literal></term>
7142       <listitem>
7143        <para>
7144         The day of the year (1 - 365/366)
7145        </para>
7146
7147 <screen>
7148 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
7149 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
7150 </screen>
7151       </listitem>
7152      </varlistentry>
7153
7154      <varlistentry>
7155       <term><literal>epoch</literal></term>
7156       <listitem>
7157        <para>
7158         For <type>timestamp with time zone</type> values, the
7159         number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
7160         for <type>date</type> and <type>timestamp</type> values, the
7161         number of seconds since 1970-01-01 00:00:00 local time;
7162         for <type>interval</type> values, the total number
7163         of seconds in the interval
7164        </para>
7165
7166 <screen>
7167 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
7168 <lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput>
7169
7170 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
7171 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
7172 </screen>
7173
7174        <para>
7175         Here is how you can convert an epoch value back to a time
7176         stamp:
7177        </para>
7178 <screen>
7179 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second';
7180 </screen>
7181        <para>
7182         (The <function>to_timestamp</> function encapsulates the above
7183         conversion.)
7184        </para>
7185       </listitem>
7186      </varlistentry>
7187
7188      <varlistentry>
7189       <term><literal>hour</literal></term>
7190       <listitem>
7191        <para>
7192         The hour field (0 - 23)
7193        </para>
7194
7195 <screen>
7196 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
7197 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
7198 </screen>
7199       </listitem>
7200      </varlistentry>
7201
7202      <varlistentry>
7203       <term><literal>isodow</literal></term>
7204       <listitem>
7205        <para>
7206         The day of the week as Monday (<literal>1</>) to
7207         Sunday (<literal>7</>)
7208        </para>
7209
7210 <screen>
7211 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
7212 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
7213 </screen>
7214        <para>
7215         This is identical to <literal>dow</> except for Sunday.  This
7216         matches the <acronym>ISO</> 8601 day of the week numbering.
7217        </para>
7218
7219       </listitem>
7220      </varlistentry>
7221
7222      <varlistentry>
7223       <term><literal>isoyear</literal></term>
7224       <listitem>
7225        <para>
7226         The <acronym>ISO</acronym> 8601 week-numbering year that the date
7227         falls in (not applicable to intervals)
7228        </para>
7229
7230 <screen>
7231 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
7232 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
7233 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
7234 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
7235 </screen>
7236
7237        <para>
7238         Each <acronym>ISO</acronym> 8601 week-numbering year begins with the
7239         Monday of the week containing the 4th of January, so in early
7240         January or late December the <acronym>ISO</acronym> year may be
7241         different from the Gregorian year.  See the <literal>week</literal>
7242         field for more information.
7243        </para>
7244        <para>
7245         This field is not available in PostgreSQL releases prior to 8.3.
7246        </para>
7247       </listitem>
7248      </varlistentry>
7249
7250      <varlistentry>
7251       <term><literal>microseconds</literal></term>
7252       <listitem>
7253        <para>
7254         The seconds field, including fractional parts, multiplied by 1
7255         000 000;  note that this includes full seconds
7256        </para>
7257
7258 <screen>
7259 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
7260 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
7261 </screen>
7262       </listitem>
7263      </varlistentry>
7264
7265      <varlistentry>
7266       <term><literal>millennium</literal></term>
7267       <listitem>
7268        <para>
7269         The millennium
7270        </para>
7271
7272 <screen>
7273 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
7274 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
7275 </screen>
7276
7277        <para>
7278         Years in the 1900s are in the second millennium.
7279         The third millennium started January 1, 2001.
7280        </para>
7281       </listitem>
7282      </varlistentry>
7283
7284      <varlistentry>
7285       <term><literal>milliseconds</literal></term>
7286       <listitem>
7287        <para>
7288         The seconds field, including fractional parts, multiplied by
7289         1000.  Note that this includes full seconds.
7290        </para>
7291
7292 <screen>
7293 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
7294 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
7295 </screen>
7296       </listitem>
7297      </varlistentry>
7298
7299      <varlistentry>
7300       <term><literal>minute</literal></term>
7301       <listitem>
7302        <para>
7303         The minutes field (0 - 59)
7304        </para>
7305
7306 <screen>
7307 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
7308 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
7309 </screen>
7310       </listitem>
7311      </varlistentry>
7312
7313      <varlistentry>
7314       <term><literal>month</literal></term>
7315       <listitem>
7316        <para>
7317         For <type>timestamp</type> values, the number of the month
7318         within the year (1 - 12) ; for <type>interval</type> values,
7319         the number of months, modulo 12 (0 - 11)
7320        </para>
7321
7322 <screen>
7323 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
7324 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
7325
7326 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
7327 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
7328
7329 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
7330 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7331 </screen>
7332       </listitem>
7333      </varlistentry>
7334
7335      <varlistentry>
7336       <term><literal>quarter</literal></term>
7337       <listitem>
7338        <para>
7339         The quarter of the year (1 - 4) that the date is in
7340        </para>
7341
7342 <screen>
7343 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
7344 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7345 </screen>
7346       </listitem>
7347      </varlistentry>
7348
7349      <varlistentry>
7350       <term><literal>second</literal></term>
7351       <listitem>
7352        <para>
7353         The seconds field, including fractional parts (0 -
7354         59<footnote><simpara>60 if leap seconds are
7355         implemented by the operating system</simpara></footnote>)
7356        </para>
7357
7358 <screen>
7359 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
7360 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
7361
7362 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
7363 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
7364 </screen>
7365       </listitem>
7366      </varlistentry>
7367      <varlistentry>
7368       <term><literal>timezone</literal></term>
7369       <listitem>
7370        <para>
7371         The time zone offset from UTC, measured in seconds.  Positive values
7372         correspond to time zones east of UTC, negative values to
7373         zones west of UTC.  (Technically,
7374         <productname>PostgreSQL</productname> uses <acronym>UT1</> because
7375         leap seconds are not handled.)
7376        </para>
7377       </listitem>
7378      </varlistentry>
7379
7380      <varlistentry>
7381       <term><literal>timezone_hour</literal></term>
7382       <listitem>
7383        <para>
7384         The hour component of the time zone offset
7385        </para>
7386       </listitem>
7387      </varlistentry>
7388
7389      <varlistentry>
7390       <term><literal>timezone_minute</literal></term>
7391       <listitem>
7392        <para>
7393         The minute component of the time zone offset
7394        </para>
7395       </listitem>
7396      </varlistentry>
7397
7398      <varlistentry>
7399       <term><literal>week</literal></term>
7400       <listitem>
7401        <para>
7402         The number of the <acronym>ISO</acronym> 8601 week-numbering week of
7403         the year.  By definition, ISO weeks start on Mondays and the first
7404         week of a year contains January 4 of that year.  In other words, the
7405         first Thursday of a year is in week 1 of that year.
7406        </para>
7407        <para>
7408         In the ISO week-numbering system, it is possible for early-January
7409         dates to be part of the 52nd or 53rd week of the previous year, and for
7410         late-December dates to be part of the first week of the next year.
7411         For example, <literal>2005-01-01</> is part of the 53rd week of year
7412         2004, and <literal>2006-01-01</> is part of the 52nd week of year
7413         2005, while <literal>2012-12-31</> is part of the first week of 2013.
7414         It's recommended to use the <literal>isoyear</> field together with
7415         <literal>week</> to get consistent results.
7416        </para>
7417
7418 <screen>
7419 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
7420 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
7421 </screen>
7422       </listitem>
7423      </varlistentry>
7424
7425      <varlistentry>
7426       <term><literal>year</literal></term>
7427       <listitem>
7428        <para>
7429         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting
7430         <literal>BC</> years from <literal>AD</> years should be done with care.
7431        </para>
7432
7433 <screen>
7434 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
7435 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
7436 </screen>
7437       </listitem>
7438      </varlistentry>
7439
7440     </variablelist>
7441    </para>
7442
7443    <para>
7444     The <function>extract</function> function is primarily intended
7445     for computational processing.  For formatting date/time values for
7446     display, see <xref linkend="functions-formatting">.
7447    </para>
7448
7449    <para>
7450     The <function>date_part</function> function is modeled on the traditional
7451     <productname>Ingres</productname> equivalent to the
7452     <acronym>SQL</acronym>-standard function <function>extract</function>:
7453 <synopsis>
7454 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
7455 </synopsis>
7456     Note that here the <replaceable>field</replaceable> parameter needs to
7457     be a string value, not a name.  The valid field names for
7458     <function>date_part</function> are the same as for
7459     <function>extract</function>.
7460    </para>
7461
7462 <screen>
7463 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
7464 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
7465
7466 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
7467 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
7468 </screen>
7469
7470   </sect2>
7471
7472   <sect2 id="functions-datetime-trunc">
7473    <title><function>date_trunc</function></title>
7474
7475    <indexterm>
7476     <primary>date_trunc</primary>
7477    </indexterm>
7478
7479    <para>
7480     The function <function>date_trunc</function> is conceptually
7481     similar to the <function>trunc</function> function for numbers.
7482    </para>
7483
7484    <para>
7485 <synopsis>
7486 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
7487 </synopsis>
7488     <replaceable>source</replaceable> is a value expression of type
7489     <type>timestamp</type> or <type>interval</>.
7490     (Values of type <type>date</type> and
7491     <type>time</type> are cast automatically to <type>timestamp</type> or
7492     <type>interval</>, respectively.)
7493     <replaceable>field</replaceable> selects to which precision to
7494     truncate the input value.  The return value is of type
7495     <type>timestamp</type> or <type>interval</>
7496     with all fields that are less significant than the
7497     selected one set to zero (or one, for day and month).
7498    </para>
7499
7500    <para>
7501     Valid values for <replaceable>field</replaceable> are:
7502     <simplelist>
7503      <member><literal>microseconds</literal></member>
7504      <member><literal>milliseconds</literal></member>
7505      <member><literal>second</literal></member>
7506      <member><literal>minute</literal></member>
7507      <member><literal>hour</literal></member>
7508      <member><literal>day</literal></member>
7509      <member><literal>week</literal></member>
7510      <member><literal>month</literal></member>
7511      <member><literal>quarter</literal></member>
7512      <member><literal>year</literal></member>
7513      <member><literal>decade</literal></member>
7514      <member><literal>century</literal></member>
7515      <member><literal>millennium</literal></member>
7516     </simplelist>
7517    </para>
7518
7519    <para>
7520     Examples:
7521 <screen>
7522 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
7523 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
7524
7525 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
7526 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
7527 </screen>
7528    </para>
7529   </sect2>
7530
7531   <sect2 id="functions-datetime-zoneconvert">
7532    <title><literal>AT TIME ZONE</literal></title>
7533
7534    <indexterm>
7535     <primary>time zone</primary>
7536     <secondary>conversion</secondary>
7537    </indexterm>
7538
7539    <indexterm>
7540     <primary>AT TIME ZONE</primary>
7541    </indexterm>
7542
7543    <para>
7544     The <literal>AT TIME ZONE</literal> construct allows conversions
7545     of time stamps to different time zones.  <xref
7546     linkend="functions-datetime-zoneconvert-table"> shows its
7547     variants.
7548    </para>
7549
7550     <table id="functions-datetime-zoneconvert-table">
7551      <title><literal>AT TIME ZONE</literal> Variants</title>
7552      <tgroup cols="3">
7553       <thead>
7554        <row>
7555         <entry>Expression</entry>
7556         <entry>Return Type</entry>
7557         <entry>Description</entry>
7558        </row>
7559       </thead>
7560
7561       <tbody>
7562        <row>
7563         <entry>
7564          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7565         </entry>
7566         <entry><type>timestamp with time zone</type></entry>
7567         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
7568        </row>
7569
7570        <row>
7571         <entry>
7572          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7573         </entry>
7574         <entry><type>timestamp without time zone</type></entry>
7575         <entry>Convert given time stamp <emphasis>with time zone</> to the new time
7576         zone, with no time zone designation</entry>
7577        </row>
7578
7579        <row>
7580         <entry>
7581          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7582         </entry>
7583         <entry><type>time with time zone</type></entry>
7584         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
7585        </row>
7586       </tbody>
7587      </tgroup>
7588     </table>
7589
7590    <para>
7591     In these expressions, the desired time zone <replaceable>zone</> can be
7592     specified either as a text string (e.g., <literal>'PST'</literal>)
7593     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
7594     In the text case, a time zone name can be specified in any of the ways
7595     described in <xref linkend="datatype-timezones">.
7596    </para>
7597
7598    <para>
7599     Examples (assuming the local time zone is <literal>PST8PDT</>):
7600 <screen>
7601 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
7602 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
7603
7604 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
7605 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
7606 </screen>
7607     The first example takes a time stamp without time zone and interprets it as MST time
7608     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes
7609     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
7610    </para>
7611
7612    <para>
7613     The function <literal><function>timezone</function>(<replaceable>zone</>,
7614     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
7615     <literal><replaceable>timestamp</> AT TIME ZONE
7616     <replaceable>zone</></literal>.
7617    </para>
7618   </sect2>
7619
7620   <sect2 id="functions-datetime-current">
7621    <title>Current Date/Time</title>
7622
7623    <indexterm>
7624     <primary>date</primary>
7625     <secondary>current</secondary>
7626    </indexterm>
7627
7628    <indexterm>
7629     <primary>time</primary>
7630     <secondary>current</secondary>
7631    </indexterm>
7632
7633    <para>
7634     <productname>PostgreSQL</productname> provides a number of functions
7635     that return values related to the current date and time.  These
7636     SQL-standard functions all return values based on the start time of
7637     the current transaction:
7638 <synopsis>
7639 CURRENT_DATE
7640 CURRENT_TIME
7641 CURRENT_TIMESTAMP
7642 CURRENT_TIME(<replaceable>precision</replaceable>)
7643 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
7644 LOCALTIME
7645 LOCALTIMESTAMP
7646 LOCALTIME(<replaceable>precision</replaceable>)
7647 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
7648 </synopsis>
7649     </para>
7650
7651     <para>
7652      <function>CURRENT_TIME</function> and
7653      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
7654      <function>LOCALTIME</function> and
7655      <function>LOCALTIMESTAMP</function> deliver values without time zone.
7656     </para>
7657
7658     <para>
7659      <function>CURRENT_TIME</function>,
7660      <function>CURRENT_TIMESTAMP</function>,
7661      <function>LOCALTIME</function>, and
7662      <function>LOCALTIMESTAMP</function>
7663      can optionally take
7664      a precision parameter, which causes the result to be rounded
7665      to that many fractional digits in the seconds field.  Without a precision parameter,
7666      the result is given to the full available precision.
7667     </para>
7668
7669    <para>
7670     Some examples:
7671 <screen>
7672 SELECT CURRENT_TIME;
7673 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
7674
7675 SELECT CURRENT_DATE;
7676 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
7677
7678 SELECT CURRENT_TIMESTAMP;
7679 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
7680
7681 SELECT CURRENT_TIMESTAMP(2);
7682 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
7683
7684 SELECT LOCALTIMESTAMP;
7685 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
7686 </screen>
7687    </para>
7688
7689    <para>
7690     Since these functions return
7691     the start time of the current transaction, their values do not
7692     change during the transaction. This is considered a feature:
7693     the intent is to allow a single transaction to have a consistent
7694     notion of the <quote>current</quote> time, so that multiple
7695     modifications within the same transaction bear the same
7696     time stamp.
7697    </para>
7698
7699    <note>
7700     <para>
7701      Other database systems might advance these values more
7702      frequently.
7703     </para>
7704    </note>
7705
7706    <para>
7707     <productname>PostgreSQL</productname> also provides functions that
7708     return the start time of the current statement, as well as the actual
7709     current time at the instant the function is called.  The complete list
7710     of non-SQL-standard time functions is:
7711 <synopsis>
7712 transaction_timestamp()
7713 statement_timestamp()
7714 clock_timestamp()
7715 timeofday()
7716 now()
7717 </synopsis>
7718    </para>
7719
7720    <para>
7721     <function>transaction_timestamp()</> is equivalent to
7722     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
7723     what it returns.
7724     <function>statement_timestamp()</> returns the start time of the current
7725     statement (more specifically, the time of receipt of the latest command
7726     message from the client).
7727     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
7728     return the same value during the first command of a transaction, but might
7729     differ during subsequent commands.
7730     <function>clock_timestamp()</> returns the actual current time, and
7731     therefore its value changes even within a single SQL command.
7732     <function>timeofday()</> is a historical
7733     <productname>PostgreSQL</productname> function.  Like
7734     <function>clock_timestamp()</>, it returns the actual current time,
7735     but as a formatted <type>text</> string rather than a <type>timestamp
7736     with time zone</> value.
7737     <function>now()</> is a traditional <productname>PostgreSQL</productname>
7738     equivalent to <function>transaction_timestamp()</function>.
7739    </para>
7740
7741    <para>
7742     All the date/time data types also accept the special literal value
7743     <literal>now</literal> to specify the current date and time (again,
7744     interpreted as the transaction start time).  Thus,
7745     the following three all return the same result:
7746 <programlisting>
7747 SELECT CURRENT_TIMESTAMP;
7748 SELECT now();
7749 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
7750 </programlisting>
7751    </para>
7752
7753     <tip>
7754      <para>
7755       You do not want to use the third form when specifying a <literal>DEFAULT</>
7756       clause while creating a table.  The system will convert <literal>now</literal>
7757       to a <type>timestamp</type> as soon as the constant is parsed, so that when
7758       the default value is needed,
7759       the time of the table creation would be used!  The first two
7760       forms will not be evaluated until the default value is used,
7761       because they are function calls.  Thus they will give the desired
7762       behavior of defaulting to the time of row insertion.
7763      </para>
7764     </tip>
7765   </sect2>
7766
7767   <sect2 id="functions-datetime-delay">
7768    <title>Delaying Execution</title>
7769
7770    <indexterm>
7771     <primary>pg_sleep</primary>
7772    </indexterm>
7773    <indexterm>
7774     <primary>pg_sleep_for</primary>
7775    </indexterm>
7776    <indexterm>
7777     <primary>pg_sleep_until</primary>
7778    </indexterm>
7779    <indexterm>
7780     <primary>sleep</primary>
7781    </indexterm>
7782    <indexterm>
7783     <primary>delay</primary>
7784    </indexterm>
7785
7786    <para>
7787     The following functions are available to delay execution of the server
7788     process:
7789 <synopsis>
7790 pg_sleep(<replaceable>seconds</replaceable>)
7791 pg_sleep_for(<type>interval</>)
7792 pg_sleep_until(<type>timestamp with time zone</>)
7793 </synopsis>
7794
7795     <function>pg_sleep</function> makes the current session's process
7796     sleep until <replaceable>seconds</replaceable> seconds have
7797     elapsed.  <replaceable>seconds</replaceable> is a value of type
7798     <type>double precision</>, so fractional-second delays can be specified.
7799     <function>pg_sleep_for</function> is a convenience function for larger
7800     sleep times specified as an <type>interval</>.
7801     <function>pg_sleep_until</function> is a convenience function for when
7802     a specific wake-up time is desired.
7803     For example:
7804
7805 <programlisting>
7806 SELECT pg_sleep(1.5);
7807 SELECT pg_sleep_for('5 minutes');
7808 SELECT pg_sleep_until('tomorrow 03:00');
7809 </programlisting>
7810    </para>
7811
7812    <note>
7813      <para>
7814       The effective resolution of the sleep interval is platform-specific;
7815       0.01 seconds is a common value.  The sleep delay will be at least as long
7816       as specified. It might be longer depending on factors such as server load.
7817       In particular, <function>pg_sleep_until</function> is not guaranteed to
7818       wake up exactly at the specified time, but it will not wake up any earlier.
7819      </para>
7820    </note>
7821
7822    <warning>
7823      <para>
7824       Make sure that your session does not hold more locks than necessary
7825       when calling <function>pg_sleep</function> or its variants.  Otherwise
7826       other sessions might have to wait for your sleeping process, slowing down
7827       the entire system.
7828      </para>
7829    </warning>
7830   </sect2>
7831
7832  </sect1>
7833
7834
7835  <sect1 id="functions-enum">
7836   <title>Enum Support Functions</title>
7837
7838   <para>
7839    For enum types (described in <xref linkend="datatype-enum">),
7840    there are several functions that allow cleaner programming without
7841    hard-coding particular values of an enum type.
7842    These are listed in <xref linkend="functions-enum-table">. The examples
7843    assume an enum type created as:
7844
7845 <programlisting>
7846 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
7847 </programlisting>
7848
7849   </para>
7850
7851   <table id="functions-enum-table">
7852     <title>Enum Support Functions</title>
7853     <tgroup cols="4">
7854      <thead>
7855       <row>
7856        <entry>Function</entry>
7857        <entry>Description</entry>
7858        <entry>Example</entry>
7859        <entry>Example Result</entry>
7860       </row>
7861      </thead>
7862      <tbody>
7863       <row>
7864        <entry>
7865          <indexterm>
7866           <primary>enum_first</primary>
7867          </indexterm>
7868          <literal>enum_first(anyenum)</literal>
7869        </entry>
7870        <entry>Returns the first value of the input enum type</entry>
7871        <entry><literal>enum_first(null::rainbow)</literal></entry>
7872        <entry><literal>red</literal></entry>
7873       </row>
7874       <row>
7875        <entry>
7876          <indexterm>
7877           <primary>enum_last</primary>
7878          </indexterm>
7879          <literal>enum_last(anyenum)</literal>
7880        </entry>
7881        <entry>Returns the last value of the input enum type</entry>
7882        <entry><literal>enum_last(null::rainbow)</literal></entry>
7883        <entry><literal>purple</literal></entry>
7884       </row>
7885       <row>
7886        <entry>
7887          <indexterm>
7888           <primary>enum_range</primary>
7889          </indexterm>
7890          <literal>enum_range(anyenum)</literal>
7891        </entry>
7892        <entry>Returns all values of the input enum type in an ordered array</entry>
7893        <entry><literal>enum_range(null::rainbow)</literal></entry>
7894        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
7895       </row>
7896       <row>
7897        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
7898        <entry morerows="2">
7899         Returns the range between the two given enum values, as an ordered
7900         array. The values must be from the same enum type. If the first
7901         parameter is null, the result will start with the first value of
7902         the enum type.
7903         If the second parameter is null, the result will end with the last
7904         value of the enum type.
7905        </entry>
7906        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
7907        <entry><literal>{orange,yellow,green}</literal></entry>
7908       </row>
7909       <row>
7910        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
7911        <entry><literal>{red,orange,yellow,green}</literal></entry>
7912       </row>
7913       <row>
7914        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
7915        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
7916       </row>
7917      </tbody>
7918     </tgroup>
7919    </table>
7920
7921    <para>
7922     Notice that except for the two-argument form of <function>enum_range</>,
7923     these functions disregard the specific value passed to them; they care
7924     only about its declared data type.  Either null or a specific value of
7925     the type can be passed, with the same result.  It is more common to
7926     apply these functions to a table column or function argument than to
7927     a hardwired type name as suggested by the examples.
7928    </para>
7929  </sect1>
7930
7931  <sect1 id="functions-geometry">
7932   <title>Geometric Functions and Operators</title>
7933
7934    <para>
7935     The geometric types <type>point</type>, <type>box</type>,
7936     <type>lseg</type>, <type>line</type>, <type>path</type>,
7937     <type>polygon</type>, and <type>circle</type> have a large set of
7938     native support functions and operators, shown in <xref
7939     linkend="functions-geometry-op-table">, <xref
7940     linkend="functions-geometry-func-table">, and <xref
7941     linkend="functions-geometry-conv-table">.
7942    </para>
7943
7944    <caution>
7945     <para>
7946      Note that the <quote>same as</> operator, <literal>~=</>, represents
7947      the usual notion of equality for the <type>point</type>,
7948      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
7949      Some of these types also have an <literal>=</> operator, but
7950      <literal>=</> compares
7951      for equal <emphasis>areas</> only.  The other scalar comparison operators
7952      (<literal>&lt;=</> and so on) likewise compare areas for these types.
7953     </para>
7954    </caution>
7955
7956    <table id="functions-geometry-op-table">
7957      <title>Geometric Operators</title>
7958      <tgroup cols="3">
7959       <thead>
7960        <row>
7961         <entry>Operator</entry>
7962         <entry>Description</entry>
7963         <entry>Example</entry>
7964        </row>
7965       </thead>
7966       <tbody>
7967        <row>
7968         <entry> <literal>+</literal> </entry>
7969         <entry>Translation</entry>
7970         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
7971        </row>
7972        <row>
7973         <entry> <literal>-</literal> </entry>
7974         <entry>Translation</entry>
7975         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
7976        </row>
7977        <row>
7978         <entry> <literal>*</literal> </entry>
7979         <entry>Scaling/rotation</entry>
7980         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
7981        </row>
7982        <row>
7983         <entry> <literal>/</literal> </entry>
7984         <entry>Scaling/rotation</entry>
7985         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
7986        </row>
7987        <row>
7988         <entry> <literal>#</literal> </entry>
7989         <entry>Point or box of intersection</entry>
7990         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
7991        </row>
7992        <row>
7993         <entry> <literal>#</literal> </entry>
7994         <entry>Number of points in path or polygon</entry>
7995         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
7996        </row>
7997        <row>
7998         <entry> <literal>@-@</literal> </entry>
7999         <entry>Length or circumference</entry>
8000         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
8001        </row>
8002        <row>
8003         <entry> <literal>@@</literal> </entry>
8004         <entry>Center</entry>
8005         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
8006        </row>
8007        <row>
8008         <entry> <literal>##</literal> </entry>
8009         <entry>Closest point to first operand on second operand</entry>
8010         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
8011        </row>
8012        <row>
8013         <entry> <literal>&lt;-&gt;</literal> </entry>
8014         <entry>Distance between</entry>
8015         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
8016        </row>
8017        <row>
8018         <entry> <literal>&amp;&amp;</literal> </entry>
8019         <entry>Overlaps?  (One point in common makes this true.)</entry>
8020         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
8021        </row>
8022        <row>
8023         <entry> <literal>&lt;&lt;</literal> </entry>
8024         <entry>Is strictly left of?</entry>
8025         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
8026        </row>
8027        <row>
8028         <entry> <literal>&gt;&gt;</literal> </entry>
8029         <entry>Is strictly right of?</entry>
8030         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
8031        </row>
8032        <row>
8033         <entry> <literal>&amp;&lt;</literal> </entry>
8034         <entry>Does not extend to the right of?</entry>
8035         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
8036        </row>
8037        <row>
8038         <entry> <literal>&amp;&gt;</literal> </entry>
8039         <entry>Does not extend to the left of?</entry>
8040         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
8041        </row>
8042        <row>
8043         <entry> <literal>&lt;&lt;|</literal> </entry>
8044         <entry>Is strictly below?</entry>
8045         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
8046        </row>
8047        <row>
8048         <entry> <literal>|&gt;&gt;</literal> </entry>
8049         <entry>Is strictly above?</entry>
8050         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
8051        </row>
8052        <row>
8053         <entry> <literal>&amp;&lt;|</literal> </entry>
8054         <entry>Does not extend above?</entry>
8055         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
8056        </row>
8057        <row>
8058         <entry> <literal>|&amp;&gt;</literal> </entry>
8059         <entry>Does not extend below?</entry>
8060         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
8061        </row>
8062        <row>
8063         <entry> <literal>&lt;^</literal> </entry>
8064         <entry>Is below (allows touching)?</entry>
8065         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
8066        </row>
8067        <row>
8068         <entry> <literal>&gt;^</literal> </entry>
8069         <entry>Is above (allows touching)?</entry>
8070         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
8071        </row>
8072        <row>
8073         <entry> <literal>?#</literal> </entry>
8074         <entry>Intersects?</entry>
8075         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
8076        </row>
8077        <row>
8078         <entry> <literal>?-</literal> </entry>
8079         <entry>Is horizontal?</entry>
8080         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
8081        </row>
8082        <row>
8083         <entry> <literal>?-</literal> </entry>
8084         <entry>Are horizontally aligned?</entry>
8085         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
8086        </row>
8087        <row>
8088         <entry> <literal>?|</literal> </entry>
8089         <entry>Is vertical?</entry>
8090         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
8091        </row>
8092        <row>
8093         <entry> <literal>?|</literal> </entry>
8094         <entry>Are vertically aligned?</entry>
8095         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
8096        </row>
8097        <row>
8098         <entry> <literal>?-|</literal> </entry>
8099         <entry>Is perpendicular?</entry>
8100         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
8101        </row>
8102        <row>
8103         <entry> <literal>?||</literal> </entry>
8104         <entry>Are parallel?</entry>
8105         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
8106        </row>
8107        <row>
8108         <entry> <literal>@&gt;</literal> </entry>
8109         <entry>Contains?</entry>
8110         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
8111        </row>
8112        <row>
8113         <entry> <literal>&lt;@</literal> </entry>
8114         <entry>Contained in or on?</entry>
8115         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
8116        </row>
8117        <row>
8118         <entry> <literal>~=</literal> </entry>
8119         <entry>Same as?</entry>
8120         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
8121        </row>
8122       </tbody>
8123      </tgroup>
8124    </table>
8125
8126    <note>
8127     <para>
8128      Before <productname>PostgreSQL</productname> 8.2, the containment
8129      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
8130      called <literal>~</> and <literal>@</>.  These names are still
8131      available, but are deprecated and will eventually be removed.
8132     </para>
8133    </note>
8134
8135    <indexterm>
8136     <primary>area</primary>
8137    </indexterm>
8138    <indexterm>
8139     <primary>center</primary>
8140    </indexterm>
8141    <indexterm>
8142     <primary>diameter</primary>
8143    </indexterm>
8144    <indexterm>
8145     <primary>height</primary>
8146    </indexterm>
8147    <indexterm>
8148     <primary>isclosed</primary>
8149    </indexterm>
8150    <indexterm>
8151     <primary>isopen</primary>
8152    </indexterm>
8153    <indexterm>
8154     <primary>length</primary>
8155    </indexterm>
8156    <indexterm>
8157     <primary>npoints</primary>
8158    </indexterm>
8159    <indexterm>
8160     <primary>pclose</primary>
8161    </indexterm>
8162    <indexterm>
8163     <primary>popen</primary>
8164    </indexterm>
8165    <indexterm>
8166     <primary>radius</primary>
8167    </indexterm>
8168    <indexterm>
8169     <primary>width</primary>
8170    </indexterm>
8171
8172    <table id="functions-geometry-func-table">
8173      <title>Geometric Functions</title>
8174      <tgroup cols="4">
8175       <thead>
8176        <row>
8177         <entry>Function</entry>
8178         <entry>Return Type</entry>
8179         <entry>Description</entry>
8180         <entry>Example</entry>
8181        </row>
8182       </thead>
8183       <tbody>
8184        <row>
8185         <entry><literal><function>area(<replaceable>object</>)</function></literal></entry>
8186         <entry><type>double precision</type></entry>
8187         <entry>area</entry>
8188         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
8189        </row>
8190        <row>
8191         <entry><literal><function>center(<replaceable>object</>)</function></literal></entry>
8192         <entry><type>point</type></entry>
8193         <entry>center</entry>
8194         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
8195        </row>
8196        <row>
8197         <entry><literal><function>diameter(<type>circle</>)</function></literal></entry>
8198         <entry><type>double precision</type></entry>
8199         <entry>diameter of circle</entry>
8200         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
8201        </row>
8202        <row>
8203         <entry><literal><function>height(<type>box</>)</function></literal></entry>
8204         <entry><type>double precision</type></entry>
8205         <entry>vertical size of box</entry>
8206         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
8207        </row>
8208        <row>
8209         <entry><literal><function>isclosed(<type>path</>)</function></literal></entry>
8210         <entry><type>boolean</type></entry>
8211         <entry>a closed path?</entry>
8212         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
8213        </row>
8214        <row>
8215         <entry><literal><function>isopen(<type>path</>)</function></literal></entry>
8216         <entry><type>boolean</type></entry>
8217         <entry>an open path?</entry>
8218         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
8219        </row>
8220        <row>
8221         <entry><literal><function>length(<replaceable>object</>)</function></literal></entry>
8222         <entry><type>double precision</type></entry>
8223         <entry>length</entry>
8224         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
8225        </row>
8226        <row>
8227         <entry><literal><function>npoints(<type>path</>)</function></literal></entry>
8228         <entry><type>int</type></entry>
8229         <entry>number of points</entry>
8230         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
8231        </row>
8232        <row>
8233         <entry><literal><function>npoints(<type>polygon</>)</function></literal></entry>
8234         <entry><type>int</type></entry>
8235         <entry>number of points</entry>
8236         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
8237        </row>
8238        <row>
8239         <entry><literal><function>pclose(<type>path</>)</function></literal></entry>
8240         <entry><type>path</type></entry>
8241         <entry>convert path to closed</entry>
8242         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
8243        </row>
8244 <![IGNORE[
8245 <!-- Not defined by this name. Implements the intersection operator '#' -->
8246        <row>
8247         <entry><literal><function>point(<type>lseg</>, <type>lseg</>)</function></literal></entry>
8248         <entry><type>point</type></entry>
8249         <entry>intersection</entry>
8250         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
8251        </row>
8252 ]]>
8253        <row>
8254         <entry><literal><function>popen(<type>path</>)</function></literal></entry>
8255         <entry><type>path</type></entry>
8256         <entry>convert path to open</entry>
8257         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
8258        </row>
8259        <row>
8260         <entry><literal><function>radius(<type>circle</type>)</function></literal></entry>
8261         <entry><type>double precision</type></entry>
8262         <entry>radius of circle</entry>
8263         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
8264        </row>
8265        <row>
8266         <entry><literal><function>width(<type>box</>)</function></literal></entry>
8267         <entry><type>double precision</type></entry>
8268         <entry>horizontal size of box</entry>
8269         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
8270        </row>
8271       </tbody>
8272      </tgroup>
8273    </table>
8274
8275    <table id="functions-geometry-conv-table">
8276      <title>Geometric Type Conversion Functions</title>
8277      <tgroup cols="4">
8278       <thead>
8279        <row>
8280         <entry>Function</entry>
8281         <entry>Return Type</entry>
8282         <entry>Description</entry>
8283         <entry>Example</entry>
8284        </row>
8285       </thead>
8286       <tbody>
8287        <row>
8288         <entry>
8289          <indexterm>
8290           <primary>box</primary>
8291          </indexterm>
8292          <literal><function>box(<type>circle</type>)</function></literal>
8293         </entry>
8294         <entry><type>box</type></entry>
8295         <entry>circle to box</entry>
8296         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
8297        </row>
8298        <row>
8299         <entry><literal><function>box(<type>point</type>)</function></literal></entry>
8300         <entry><type>box</type></entry>
8301         <entry>point to empty box</entry>
8302         <entry><literal>box(point '(0,0)')</literal></entry>
8303        </row>
8304        <row>
8305         <entry><literal><function>box(<type>point</type>, <type>point</type>)</function></literal></entry>
8306         <entry><type>box</type></entry>
8307         <entry>points to box</entry>
8308         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
8309        </row>
8310        <row>
8311         <entry><literal><function>box(<type>polygon</type>)</function></literal></entry>
8312         <entry><type>box</type></entry>
8313         <entry>polygon to box</entry>
8314         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8315        </row>
8316        <row>
8317         <entry><literal><function>bound_box(<type>box</type>, <type>box</type>)</function></literal></entry>
8318         <entry><type>box</type></entry>
8319         <entry>boxes to bounding box</entry>
8320         <entry><literal>bound_box(box '((0,0),(1,1))', box '((3,3),(4,4))')</literal></entry>
8321        </row>
8322        <row>
8323         <entry>
8324          <indexterm>
8325           <primary>circle</primary>
8326          </indexterm>
8327          <literal><function>circle(<type>box</type>)</function></literal>
8328         </entry>
8329         <entry><type>circle</type></entry>
8330         <entry>box to circle</entry>
8331         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
8332        </row>
8333        <row>
8334         <entry><literal><function>circle(<type>point</type>, <type>double precision</type>)</function></literal></entry>
8335         <entry><type>circle</type></entry>
8336         <entry>center and radius to circle</entry>
8337         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
8338        </row>
8339        <row>
8340         <entry><literal><function>circle(<type>polygon</type>)</function></literal></entry>
8341         <entry><type>circle</type></entry>
8342         <entry>polygon to circle</entry>
8343         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8344        </row>
8345        <row>
8346         <entry><literal><function>line(<type>point</type>, <type>point</type>)</function></literal></entry>
8347         <entry><type>line</type></entry>
8348         <entry>points to line</entry>
8349         <entry><literal>line(point '(-1,0)', point '(1,0)')</literal></entry>
8350        </row>
8351        <row>
8352         <entry>
8353          <indexterm>
8354           <primary>lseg</primary>
8355          </indexterm>
8356          <literal><function>lseg(<type>box</type>)</function></literal>
8357         </entry>
8358         <entry><type>lseg</type></entry>
8359         <entry>box diagonal to line segment</entry>
8360         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
8361        </row>
8362        <row>
8363         <entry><literal><function>lseg(<type>point</type>, <type>point</type>)</function></literal></entry>
8364         <entry><type>lseg</type></entry>
8365         <entry>points to line segment</entry>
8366         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
8367        </row>
8368        <row>
8369         <entry>
8370          <indexterm>
8371           <primary>path</primary>
8372          </indexterm>
8373          <literal><function>path(<type>polygon</type>)</function></literal>
8374         </entry>
8375         <entry><type>path</type></entry>
8376         <entry>polygon to path</entry>
8377         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8378        </row>
8379        <row>
8380         <entry>
8381          <indexterm>
8382           <primary>point</primary>
8383          </indexterm>
8384          <literal><function>point</function>(<type>double
8385          precision</type>, <type>double precision</type>)</literal>
8386         </entry>
8387         <entry><type>point</type></entry>
8388         <entry>construct point</entry>
8389         <entry><literal>point(23.4, -44.5)</literal></entry>
8390        </row>
8391        <row>
8392         <entry><literal><function>point(<type>box</type>)</function></literal></entry>
8393         <entry><type>point</type></entry>
8394         <entry>center of box</entry>
8395         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
8396        </row>
8397        <row>
8398         <entry><literal><function>point(<type>circle</type>)</function></literal></entry>
8399         <entry><type>point</type></entry>
8400         <entry>center of circle</entry>
8401         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
8402        </row>
8403        <row>
8404         <entry><literal><function>point(<type>lseg</type>)</function></literal></entry>
8405         <entry><type>point</type></entry>
8406         <entry>center of line segment</entry>
8407         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
8408        </row>
8409        <row>
8410         <entry><literal><function>point(<type>polygon</type>)</function></literal></entry>
8411         <entry><type>point</type></entry>
8412         <entry>center of polygon</entry>
8413         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8414        </row>
8415        <row>
8416         <entry>
8417          <indexterm>
8418           <primary>polygon</primary>
8419          </indexterm>
8420          <literal><function>polygon(<type>box</type>)</function></literal>
8421         </entry>
8422         <entry><type>polygon</type></entry>
8423         <entry>box to 4-point polygon</entry>
8424         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
8425        </row>
8426        <row>
8427         <entry><literal><function>polygon(<type>circle</type>)</function></literal></entry>
8428         <entry><type>polygon</type></entry>
8429         <entry>circle to 12-point polygon</entry>
8430         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
8431        </row>
8432        <row>
8433         <entry><literal><function>polygon(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</function></literal></entry>
8434         <entry><type>polygon</type></entry>
8435         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
8436         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
8437        </row>
8438        <row>
8439         <entry><literal><function>polygon(<type>path</type>)</function></literal></entry>
8440         <entry><type>polygon</type></entry>
8441         <entry>path to polygon</entry>
8442         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
8443        </row>
8444       </tbody>
8445      </tgroup>
8446    </table>
8447
8448     <para>
8449      It is possible to access the two component numbers of a <type>point</>
8450      as though the point were an array with indexes 0 and 1.  For example, if
8451      <literal>t.p</> is a <type>point</> column then
8452      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
8453      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
8454      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
8455      as an array of two <type>point</> values.
8456     </para>
8457
8458     <para>
8459      The <function>area</function> function works for the types
8460      <type>box</type>, <type>circle</type>, and <type>path</type>.
8461      The <function>area</function> function only works on the
8462      <type>path</type> data type if the points in the
8463      <type>path</type> are non-intersecting.  For example, the
8464      <type>path</type>
8465      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
8466      will not work;  however, the following visually identical
8467      <type>path</type>
8468      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
8469      will work.  If the concept of an intersecting versus
8470      non-intersecting <type>path</type> is confusing, draw both of the
8471      above <type>path</type>s side by side on a piece of graph paper.
8472     </para>
8473
8474   </sect1>
8475
8476
8477  <sect1 id="functions-net">
8478   <title>Network Address Functions and Operators</title>
8479
8480   <para>
8481    <xref linkend="cidr-inet-operators-table"> shows the operators
8482    available for the <type>cidr</type> and <type>inet</type> types.
8483    The operators <literal>&lt;&lt;</literal>,
8484    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>,
8485    <literal>&gt;&gt;=</literal>, and <literal>&amp;&amp;</literal>
8486    test for subnet inclusion.  They
8487    consider only the network parts of the two addresses (ignoring any
8488    host part) and determine whether one network is identical to
8489    or a subnet of the other.
8490   </para>
8491
8492     <table id="cidr-inet-operators-table">
8493      <title><type>cidr</type> and <type>inet</type> Operators</title>
8494      <tgroup cols="3">
8495       <thead>
8496        <row>
8497         <entry>Operator</entry>
8498         <entry>Description</entry>
8499         <entry>Example</entry>
8500        </row>
8501       </thead>
8502       <tbody>
8503        <row>
8504         <entry> <literal>&lt;</literal> </entry>
8505         <entry>is less than</entry>
8506         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
8507        </row>
8508        <row>
8509         <entry> <literal>&lt;=</literal> </entry>
8510         <entry>is less than or equal</entry>
8511         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
8512        </row>
8513        <row>
8514         <entry> <literal>=</literal> </entry>
8515         <entry>equals</entry>
8516         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
8517        </row>
8518        <row>
8519         <entry> <literal>&gt;=</literal> </entry>
8520         <entry>is greater or equal</entry>
8521         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
8522        </row>
8523        <row>
8524         <entry> <literal>&gt;</literal> </entry>
8525         <entry>is greater than</entry>
8526         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
8527        </row>
8528        <row>
8529         <entry> <literal>&lt;&gt;</literal> </entry>
8530         <entry>is not equal</entry>
8531         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
8532        </row>
8533        <row>
8534         <entry> <literal>&lt;&lt;</literal> </entry>
8535         <entry>is contained by</entry>
8536         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
8537        </row>
8538        <row>
8539         <entry> <literal>&lt;&lt;=</literal> </entry>
8540         <entry>is contained by or equals</entry>
8541         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
8542        </row>
8543        <row>
8544         <entry> <literal>&gt;&gt;</literal> </entry>
8545         <entry>contains</entry>
8546         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
8547        </row>
8548        <row>
8549         <entry> <literal>&gt;&gt;=</literal> </entry>
8550         <entry>contains or equals</entry>
8551         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
8552        </row>
8553        <row>
8554         <entry> <literal>&amp;&amp;</literal> </entry>
8555         <entry>contains or is contained by</entry>
8556         <entry><literal>inet '192.168.1/24' &amp;&amp; inet '192.168.1.80/28'</literal></entry>
8557        </row>
8558        <row>
8559         <entry> <literal>~</literal> </entry>
8560         <entry>bitwise NOT</entry>
8561         <entry><literal>~ inet '192.168.1.6'</literal></entry>
8562        </row>
8563        <row>
8564         <entry> <literal>&amp;</literal> </entry>
8565         <entry>bitwise AND</entry>
8566         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
8567        </row>
8568        <row>
8569         <entry> <literal>|</literal> </entry>
8570         <entry>bitwise OR</entry>
8571         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
8572        </row>
8573        <row>
8574         <entry> <literal>+</literal> </entry>
8575         <entry>addition</entry>
8576         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
8577        </row>
8578        <row>
8579         <entry> <literal>-</literal> </entry>
8580         <entry>subtraction</entry>
8581         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
8582        </row>
8583        <row>
8584         <entry> <literal>-</literal> </entry>
8585         <entry>subtraction</entry>
8586         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
8587        </row>
8588       </tbody>
8589      </tgroup>
8590     </table>
8591
8592   <para>
8593    <xref linkend="cidr-inet-functions-table"> shows the functions
8594    available for use with the <type>cidr</type> and <type>inet</type>
8595    types.  The <function>abbrev</function>, <function>host</function>,
8596    and <function>text</function>
8597    functions are primarily intended to offer alternative display
8598    formats.
8599   </para>
8600
8601     <table id="cidr-inet-functions-table">
8602      <title><type>cidr</type> and <type>inet</type> Functions</title>
8603      <tgroup cols="5">
8604       <thead>
8605        <row>
8606         <entry>Function</entry>
8607         <entry>Return Type</entry>
8608         <entry>Description</entry>
8609         <entry>Example</entry>
8610         <entry>Result</entry>
8611        </row>
8612       </thead>
8613       <tbody>
8614        <row>
8615         <entry>
8616          <indexterm>
8617           <primary>abbrev</primary>
8618          </indexterm>
8619          <literal><function>abbrev(<type>inet</type>)</function></literal>
8620         </entry>
8621         <entry><type>text</type></entry>
8622         <entry>abbreviated display format as text</entry>
8623         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
8624         <entry><literal>10.1.0.0/16</literal></entry>
8625        </row>
8626        <row>
8627         <entry><literal><function>abbrev(<type>cidr</type>)</function></literal></entry>
8628         <entry><type>text</type></entry>
8629         <entry>abbreviated display format as text</entry>
8630         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
8631         <entry><literal>10.1/16</literal></entry>
8632        </row>
8633        <row>
8634         <entry>
8635          <indexterm>
8636           <primary>broadcast</primary>
8637          </indexterm>
8638          <literal><function>broadcast(<type>inet</type>)</function></literal>
8639         </entry>
8640         <entry><type>inet</type></entry>
8641         <entry>broadcast address for network</entry>
8642         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
8643         <entry><literal>192.168.1.255/24</literal></entry>
8644        </row>
8645        <row>
8646         <entry>
8647          <indexterm>
8648           <primary>family</primary>
8649          </indexterm>
8650          <literal><function>family(<type>inet</type>)</function></literal>
8651         </entry>
8652         <entry><type>int</type></entry>
8653         <entry>extract family of address; <literal>4</literal> for IPv4,
8654          <literal>6</literal> for IPv6</entry>
8655         <entry><literal>family('::1')</literal></entry>
8656         <entry><literal>6</literal></entry>
8657        </row>
8658        <row>
8659         <entry>
8660          <indexterm>
8661           <primary>host</primary>
8662          </indexterm>
8663          <literal><function>host(<type>inet</type>)</function></literal>
8664         </entry>
8665         <entry><type>text</type></entry>
8666         <entry>extract IP address as text</entry>
8667         <entry><literal>host('192.168.1.5/24')</literal></entry>
8668         <entry><literal>192.168.1.5</literal></entry>
8669        </row>
8670        <row>
8671         <entry>
8672          <indexterm>
8673           <primary>hostmask</primary>
8674          </indexterm>
8675          <literal><function>hostmask(<type>inet</type>)</function></literal>
8676         </entry>
8677         <entry><type>inet</type></entry>
8678         <entry>construct host mask for network</entry>
8679         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
8680         <entry><literal>0.0.0.3</literal></entry>
8681        </row>
8682        <row>
8683         <entry>
8684          <indexterm>
8685           <primary>masklen</primary>
8686          </indexterm>
8687          <literal><function>masklen(<type>inet</type>)</function></literal>
8688         </entry>
8689         <entry><type>int</type></entry>
8690         <entry>extract netmask length</entry>
8691         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
8692         <entry><literal>24</literal></entry>
8693        </row>
8694        <row>
8695         <entry>
8696          <indexterm>
8697           <primary>netmask</primary>
8698          </indexterm>
8699          <literal><function>netmask(<type>inet</type>)</function></literal>
8700         </entry>
8701         <entry><type>inet</type></entry>
8702         <entry>construct netmask for network</entry>
8703         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
8704         <entry><literal>255.255.255.0</literal></entry>
8705        </row>
8706        <row>
8707         <entry>
8708          <indexterm>
8709           <primary>network</primary>
8710          </indexterm>
8711          <literal><function>network(<type>inet</type>)</function></literal>
8712         </entry>
8713         <entry><type>cidr</type></entry>
8714         <entry>extract network part of address</entry>
8715         <entry><literal>network('192.168.1.5/24')</literal></entry>
8716         <entry><literal>192.168.1.0/24</literal></entry>
8717        </row>
8718        <row>
8719         <entry>
8720          <indexterm>
8721           <primary>set_masklen</primary>
8722          </indexterm>
8723          <literal><function>set_masklen(<type>inet</type>, <type>int</type>)</function></literal>
8724         </entry>
8725         <entry><type>inet</type></entry>
8726         <entry>set netmask length for <type>inet</type> value</entry>
8727         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
8728         <entry><literal>192.168.1.5/16</literal></entry>
8729        </row>
8730        <row>
8731         <entry><literal><function>set_masklen(<type>cidr</type>, <type>int</type>)</function></literal></entry>
8732         <entry><type>cidr</type></entry>
8733         <entry>set netmask length for <type>cidr</type> value</entry>
8734         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
8735         <entry><literal>192.168.0.0/16</literal></entry>
8736        </row>
8737        <row>
8738         <entry>
8739          <indexterm>
8740           <primary>text</primary>
8741          </indexterm>
8742          <literal><function>text(<type>inet</type>)</function></literal>
8743         </entry>
8744         <entry><type>text</type></entry>
8745         <entry>extract IP address and netmask length as text</entry>
8746         <entry><literal>text(inet '192.168.1.5')</literal></entry>
8747         <entry><literal>192.168.1.5/32</literal></entry>
8748        </row>
8749        <row>
8750         <entry>
8751          <indexterm>
8752           <primary>inet_same_family</primary>
8753          </indexterm>
8754          <literal><function>inet_same_family(<type>inet</type>, <type>inet</type>)</function></literal>
8755         </entry>
8756         <entry><type>boolean</type></entry>
8757         <entry>are the addresses from the same family?</entry>
8758         <entry><literal>inet_same_family('192.168.1.5/24', '::1')</literal></entry>
8759         <entry><literal>false</literal></entry>
8760        </row>
8761        <row>
8762         <entry>
8763          <indexterm>
8764           <primary>inet_merge</primary>
8765          </indexterm>
8766          <literal><function>inet_merge(<type>inet</type>, <type>inet</type>)</function></literal>
8767         </entry>
8768         <entry><type>cidr</type></entry>
8769         <entry>the smallest network which includes both of the given networks</entry>
8770         <entry><literal>inet_merge('192.168.1.5/24', '192.168.2.5/24')</literal></entry>
8771         <entry><literal>192.168.0.0/22</literal></entry>
8772        </row>
8773       </tbody>
8774      </tgroup>
8775     </table>
8776
8777   <para>
8778    Any <type>cidr</> value can be cast to <type>inet</> implicitly
8779    or explicitly; therefore, the functions shown above as operating on
8780    <type>inet</> also work on <type>cidr</> values.  (Where there are
8781    separate functions for <type>inet</> and <type>cidr</>, it is because
8782    the behavior should be different for the two cases.)
8783    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
8784    When this is done, any bits to the right of the netmask are silently zeroed
8785    to create a valid <type>cidr</> value.
8786    In addition,
8787    you can cast a text value to <type>inet</> or <type>cidr</>
8788    using normal casting syntax: for example,
8789    <literal>inet(<replaceable>expression</>)</literal> or
8790    <literal><replaceable>colname</>::cidr</literal>.
8791   </para>
8792
8793   <para>
8794    <xref linkend="macaddr-functions-table"> shows the functions
8795    available for use with the <type>macaddr</type> type.  The function
8796    <literal><function>trunc(<type>macaddr</type>)</function></literal> returns a MAC
8797    address with the last 3 bytes set to zero.  This can be used to
8798    associate the remaining prefix with a manufacturer.
8799   </para>
8800
8801     <table id="macaddr-functions-table">
8802      <title><type>macaddr</type> Functions</title>
8803      <tgroup cols="5">
8804       <thead>
8805        <row>
8806         <entry>Function</entry>
8807         <entry>Return Type</entry>
8808         <entry>Description</entry>
8809         <entry>Example</entry>
8810         <entry>Result</entry>
8811        </row>
8812       </thead>
8813       <tbody>
8814        <row>
8815         <entry>
8816          <indexterm>
8817           <primary>trunc</primary>
8818          </indexterm>
8819          <literal><function>trunc(<type>macaddr</type>)</function></literal>
8820         </entry>
8821         <entry><type>macaddr</type></entry>
8822         <entry>set last 3 bytes to zero</entry>
8823         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
8824         <entry><literal>12:34:56:00:00:00</literal></entry>
8825        </row>
8826       </tbody>
8827      </tgroup>
8828     </table>
8829
8830    <para>
8831     The <type>macaddr</type> type also supports the standard relational
8832     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
8833     lexicographical ordering, and the bitwise arithmetic operators
8834     (<literal>~</literal>, <literal>&amp;</literal> and <literal>|</literal>)
8835     for NOT, AND and OR.
8836    </para>
8837
8838   </sect1>
8839
8840
8841  <sect1 id="functions-textsearch">
8842   <title>Text Search Functions and Operators</title>
8843
8844    <indexterm zone="datatype-textsearch">
8845     <primary>full text search</primary>
8846     <secondary>functions and operators</secondary>
8847    </indexterm>
8848
8849    <indexterm zone="datatype-textsearch">
8850     <primary>text search</primary>
8851     <secondary>functions and operators</secondary>
8852    </indexterm>
8853
8854   <para>
8855    <xref linkend="textsearch-operators-table">,
8856    <xref linkend="textsearch-functions-table"> and
8857    <xref linkend="textsearch-functions-debug-table">
8858    summarize the functions and operators that are provided
8859    for full text searching.  See <xref linkend="textsearch"> for a detailed
8860    explanation of <productname>PostgreSQL</productname>'s text search
8861    facility.
8862   </para>
8863
8864     <table id="textsearch-operators-table">
8865      <title>Text Search Operators</title>
8866      <tgroup cols="4">
8867       <thead>
8868        <row>
8869         <entry>Operator</entry>
8870         <entry>Description</entry>
8871         <entry>Example</entry>
8872         <entry>Result</entry>
8873        </row>
8874       </thead>
8875       <tbody>
8876        <row>
8877         <entry> <literal>@@</literal> </entry>
8878         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
8879         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
8880         <entry><literal>t</literal></entry>
8881        </row>
8882        <row>
8883         <entry> <literal>@@@</literal> </entry>
8884         <entry>deprecated synonym for <literal>@@</></entry>
8885         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
8886         <entry><literal>t</literal></entry>
8887        </row>
8888        <row>
8889         <entry> <literal>||</literal> </entry>
8890         <entry>concatenate <type>tsvector</>s</entry>
8891         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
8892         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
8893        </row>
8894        <row>
8895         <entry> <literal>&amp;&amp;</literal> </entry>
8896         <entry>AND <type>tsquery</>s together</entry>
8897         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
8898         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
8899        </row>
8900        <row>
8901         <entry> <literal>||</literal> </entry>
8902         <entry>OR <type>tsquery</>s together</entry>
8903         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
8904         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
8905        </row>
8906        <row>
8907         <entry> <literal>!!</literal> </entry>
8908         <entry>negate a <type>tsquery</></entry>
8909         <entry><literal>!! 'cat'::tsquery</literal></entry>
8910         <entry><literal>!'cat'</literal></entry>
8911        </row>
8912        <row>
8913         <entry> <literal>@&gt;</literal> </entry>
8914         <entry><type>tsquery</> contains another ?</entry>
8915         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
8916         <entry><literal>f</literal></entry>
8917        </row>
8918        <row>
8919         <entry> <literal>&lt;@</literal> </entry>
8920         <entry><type>tsquery</> is contained in ?</entry>
8921         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
8922         <entry><literal>t</literal></entry>
8923        </row>
8924       </tbody>
8925      </tgroup>
8926     </table>
8927
8928     <note>
8929      <para>
8930       The <type>tsquery</> containment operators consider only the lexemes
8931       listed in the two queries, ignoring the combining operators.
8932      </para>
8933     </note>
8934
8935     <para>
8936      In addition to the operators shown in the table, the ordinary B-tree
8937      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
8938      for types <type>tsvector</> and <type>tsquery</>.  These are not very
8939      useful for text searching but allow, for example, unique indexes to be
8940      built on columns of these types.
8941     </para>
8942
8943     <table id="textsearch-functions-table">
8944      <title>Text Search Functions</title>
8945      <tgroup cols="5">
8946       <thead>
8947        <row>
8948         <entry>Function</entry>
8949         <entry>Return Type</entry>
8950         <entry>Description</entry>
8951         <entry>Example</entry>
8952         <entry>Result</entry>
8953        </row>
8954       </thead>
8955       <tbody>
8956        <row>
8957         <entry>
8958          <indexterm>
8959           <primary>get_current_ts_config</primary>
8960          </indexterm>
8961          <literal><function>get_current_ts_config()</function></literal>
8962         </entry>
8963         <entry><type>regconfig</type></entry>
8964         <entry>get default text search configuration</entry>
8965         <entry><literal>get_current_ts_config()</literal></entry>
8966         <entry><literal>english</literal></entry>
8967        </row>
8968        <row>
8969         <entry>
8970          <indexterm>
8971           <primary>length</primary>
8972          </indexterm>
8973          <literal><function>length(<type>tsvector</>)</function></literal>
8974         </entry>
8975         <entry><type>integer</type></entry>
8976         <entry>number of lexemes in <type>tsvector</></entry>
8977         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
8978         <entry><literal>3</literal></entry>
8979        </row>
8980        <row>
8981         <entry>
8982          <indexterm>
8983           <primary>numnode</primary>
8984          </indexterm>
8985          <literal><function>numnode(<type>tsquery</>)</function></literal>
8986         </entry>
8987         <entry><type>integer</type></entry>
8988         <entry>number of lexemes plus operators in <type>tsquery</></entry>
8989         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
8990         <entry><literal>5</literal></entry>
8991        </row>
8992        <row>
8993         <entry>
8994          <indexterm>
8995           <primary>plainto_tsquery</primary>
8996          </indexterm>
8997          <literal><function>plainto_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
8998         </entry>
8999         <entry><type>tsquery</type></entry>
9000         <entry>produce <type>tsquery</> ignoring punctuation</entry>
9001         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
9002         <entry><literal>'fat' &amp; 'rat'</literal></entry>
9003        </row>
9004        <row>
9005         <entry>
9006          <indexterm>
9007           <primary>querytree</primary>
9008          </indexterm>
9009          <literal><function>querytree(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</function></literal>
9010         </entry>
9011         <entry><type>text</type></entry>
9012         <entry>get indexable part of a <type>tsquery</></entry>
9013         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
9014         <entry><literal>'foo'</literal></entry>
9015        </row>
9016        <row>
9017         <entry>
9018          <indexterm>
9019           <primary>setweight</primary>
9020          </indexterm>
9021          <literal><function>setweight(<type>tsvector</>, <type>"char"</>)</function></literal>
9022         </entry>
9023         <entry><type>tsvector</type></entry>
9024         <entry>assign weight to each element of <type>tsvector</></entry>
9025         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
9026         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
9027        </row>
9028        <row>
9029         <entry>
9030          <indexterm>
9031           <primary>strip</primary>
9032          </indexterm>
9033          <literal><function>strip(<type>tsvector</>)</function></literal>
9034         </entry>
9035         <entry><type>tsvector</type></entry>
9036         <entry>remove positions and weights from <type>tsvector</></entry>
9037         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
9038         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
9039        </row>
9040        <row>
9041         <entry>
9042          <indexterm>
9043           <primary>to_tsquery</primary>
9044          </indexterm>
9045          <literal><function>to_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
9046         </entry>
9047         <entry><type>tsquery</type></entry>
9048         <entry>normalize words and convert to <type>tsquery</></entry>
9049         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
9050         <entry><literal>'fat' &amp; 'rat'</literal></entry>
9051        </row>
9052        <row>
9053         <entry>
9054          <indexterm>
9055           <primary>to_tsvector</primary>
9056          </indexterm>
9057          <literal><function>to_tsvector(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</function></literal>
9058         </entry>
9059         <entry><type>tsvector</type></entry>
9060         <entry>reduce document text to <type>tsvector</></entry>
9061         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
9062         <entry><literal>'fat':2 'rat':3</literal></entry>
9063        </row>
9064        <row>
9065         <entry>
9066          <indexterm>
9067           <primary>ts_headline</primary>
9068          </indexterm>
9069          <literal><function>ts_headline(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">document</replaceable> <type>text</>, <replaceable class="PARAMETER">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER">options</replaceable> <type>text</> </optional>)</function></literal>
9070         </entry>
9071         <entry><type>text</type></entry>
9072         <entry>display a query match</entry>
9073         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
9074         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
9075        </row>
9076        <row>
9077         <entry>
9078          <indexterm>
9079           <primary>ts_rank</primary>
9080          </indexterm>
9081          <literal><function>ts_rank(<optional> <replaceable class="PARAMETER">weights</replaceable> <type>float4[]</>, </optional> <replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER">normalization</replaceable> <type>integer</> </optional>)</function></literal>
9082         </entry>
9083         <entry><type>float4</type></entry>
9084         <entry>rank document for query</entry>
9085         <entry><literal>ts_rank(textsearch, query)</literal></entry>
9086         <entry><literal>0.818</literal></entry>
9087        </row>
9088        <row>
9089         <entry>
9090          <indexterm>
9091           <primary>ts_rank_cd</primary>
9092          </indexterm>
9093          <literal><function>ts_rank_cd(<optional> <replaceable class="PARAMETER">weights</replaceable> <type>float4[]</>, </optional> <replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER">normalization</replaceable> <type>integer</> </optional>)</function></literal>
9094         </entry>
9095         <entry><type>float4</type></entry>
9096         <entry>rank document for query using cover density</entry>
9097         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
9098         <entry><literal>2.01317</literal></entry>
9099        </row>
9100        <row>
9101         <entry>
9102          <indexterm>
9103           <primary>ts_rewrite</primary>
9104          </indexterm>
9105          <literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">target</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">substitute</replaceable> <type>tsquery</>)</function></literal>
9106         </entry>
9107         <entry><type>tsquery</type></entry>
9108         <entry>replace target with substitute within query</entry>
9109         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
9110         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
9111        </row>
9112        <row>
9113         <entry><literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</function></literal></entry>
9114         <entry><type>tsquery</type></entry>
9115         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
9116         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
9117         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
9118        </row>
9119        <row>
9120         <entry>
9121          <indexterm>
9122           <primary>tsvector_update_trigger</primary>
9123          </indexterm>
9124          <literal><function>tsvector_update_trigger()</function></literal>
9125         </entry>
9126         <entry><type>trigger</type></entry>
9127         <entry>trigger function for automatic <type>tsvector</> column update</entry>
9128         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
9129         <entry><literal></literal></entry>
9130        </row>
9131        <row>
9132         <entry>
9133          <indexterm>
9134           <primary>tsvector_update_trigger_column</primary>
9135          </indexterm>
9136          <literal><function>tsvector_update_trigger_column()</function></literal>
9137         </entry>
9138         <entry><type>trigger</type></entry>
9139         <entry>trigger function for automatic <type>tsvector</> column update</entry>
9140         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
9141         <entry><literal></literal></entry>
9142        </row>
9143       </tbody>
9144      </tgroup>
9145     </table>
9146
9147   <note>
9148    <para>
9149     All the text search functions that accept an optional <type>regconfig</>
9150     argument will use the configuration specified by
9151     <xref linkend="guc-default-text-search-config">
9152     when that argument is omitted.
9153    </para>
9154   </note>
9155
9156   <para>
9157    The functions in
9158    <xref linkend="textsearch-functions-debug-table">
9159    are listed separately because they are not usually used in everyday text
9160    searching operations.  They are helpful for development and debugging
9161    of new text search configurations.
9162   </para>
9163
9164     <table id="textsearch-functions-debug-table">
9165      <title>Text Search Debugging Functions</title>
9166      <tgroup cols="5">
9167       <thead>
9168        <row>
9169         <entry>Function</entry>
9170         <entry>Return Type</entry>
9171         <entry>Description</entry>
9172         <entry>Example</entry>
9173         <entry>Result</entry>
9174        </row>
9175       </thead>
9176       <tbody>
9177        <row>
9178         <entry>
9179          <indexterm>
9180           <primary>ts_debug</primary>
9181          </indexterm>
9182          <literal><function>ts_debug(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">document</replaceable> <type>text</>, OUT <replaceable class="PARAMETER">alias</> <type>text</>, OUT <replaceable class="PARAMETER">description</> <type>text</>, OUT <replaceable class="PARAMETER">token</> <type>text</>, OUT <replaceable class="PARAMETER">dictionaries</> <type>regdictionary[]</>, OUT <replaceable class="PARAMETER">dictionary</> <type>regdictionary</>, OUT <replaceable class="PARAMETER">lexemes</> <type>text[]</>)</function></literal>
9183         </entry>
9184         <entry><type>setof record</type></entry>
9185         <entry>test a configuration</entry>
9186         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
9187         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
9188        </row>
9189        <row>
9190         <entry>
9191          <indexterm>
9192           <primary>ts_lexize</primary>
9193          </indexterm>
9194          <literal><function>ts_lexize(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</function></literal>
9195         </entry>
9196         <entry><type>text[]</type></entry>
9197         <entry>test a dictionary</entry>
9198         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
9199         <entry><literal>{star}</literal></entry>
9200        </row>
9201        <row>
9202         <entry>
9203          <indexterm>
9204           <primary>ts_parse</primary>
9205          </indexterm>
9206          <literal><function>ts_parse(<replaceable class="PARAMETER">parser_name</replaceable> <type>text</>, <replaceable class="PARAMETER">document</replaceable> <type>text</>, OUT <replaceable class="PARAMETER">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER">token</> <type>text</>)</function></literal>
9207         </entry>
9208         <entry><type>setof record</type></entry>
9209         <entry>test a parser</entry>
9210         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
9211         <entry><literal>(1,foo) ...</literal></entry>
9212        </row>
9213        <row>
9214         <entry><literal><function>ts_parse(<replaceable class="PARAMETER">parser_oid</replaceable> <type>oid</>, <replaceable class="PARAMETER">document</replaceable> <type>text</>, OUT <replaceable class="PARAMETER">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER">token</> <type>text</>)</function></literal></entry>
9215         <entry><type>setof record</type></entry>
9216         <entry>test a parser</entry>
9217         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
9218         <entry><literal>(1,foo) ...</literal></entry>
9219        </row>
9220        <row>
9221         <entry>
9222          <indexterm>
9223           <primary>ts_token_type</primary>
9224          </indexterm>
9225          <literal><function>ts_token_type(<replaceable class="PARAMETER">parser_name</> <type>text</>, OUT <replaceable class="PARAMETER">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER">alias</> <type>text</>, OUT <replaceable class="PARAMETER">description</> <type>text</>)</function></literal>
9226         </entry>
9227         <entry><type>setof record</type></entry>
9228         <entry>get token types defined by parser</entry>
9229         <entry><literal>ts_token_type('default')</literal></entry>
9230         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
9231        </row>
9232        <row>
9233         <entry><literal><function>ts_token_type(<replaceable class="PARAMETER">parser_oid</> <type>oid</>, OUT <replaceable class="PARAMETER">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER">alias</> <type>text</>, OUT <replaceable class="PARAMETER">description</> <type>text</>)</function></literal></entry>
9234         <entry><type>setof record</type></entry>
9235         <entry>get token types defined by parser</entry>
9236         <entry><literal>ts_token_type(3722)</literal></entry>
9237         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
9238        </row>
9239        <row>
9240         <entry>
9241          <indexterm>
9242           <primary>ts_stat</primary>
9243          </indexterm>
9244          <literal><function>ts_stat(<replaceable class="PARAMETER">sqlquery</replaceable> <type>text</>, <optional> <replaceable class="PARAMETER">weights</replaceable> <type>text</>, </optional> OUT <replaceable class="PARAMETER">word</replaceable> <type>text</>, OUT <replaceable class="PARAMETER">ndoc</replaceable> <type>integer</>, OUT <replaceable class="PARAMETER">nentry</replaceable> <type>integer</>)</function></literal>
9245         </entry>
9246         <entry><type>setof record</type></entry>
9247         <entry>get statistics of a <type>tsvector</> column</entry>
9248         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
9249         <entry><literal>(foo,10,15) ...</literal></entry>
9250        </row>
9251       </tbody>
9252      </tgroup>
9253     </table>
9254
9255  </sect1>
9256
9257
9258  <sect1 id="functions-xml">
9259   <title>XML Functions</title>
9260
9261   <para>
9262    The functions and function-like expressions described in this
9263    section operate on values of type <type>xml</type>.  Check <xref
9264    linkend="datatype-xml"> for information about the <type>xml</type>
9265    type.  The function-like expressions <function>xmlparse</function>
9266    and <function>xmlserialize</function> for converting to and from
9267    type <type>xml</type> are not repeated here.  Use of most of these
9268    functions requires the installation to have been built
9269    with <command>configure --with-libxml</>.
9270   </para>
9271
9272   <sect2 id="functions-producing-xml">
9273    <title>Producing XML Content</title>
9274
9275    <para>
9276     A set of functions and function-like expressions are available for
9277     producing XML content from SQL data.  As such, they are
9278     particularly suitable for formatting query results into XML
9279     documents for processing in client applications.
9280    </para>
9281
9282    <sect3>
9283     <title><literal>xmlcomment</literal></title>
9284
9285     <indexterm>
9286      <primary>xmlcomment</primary>
9287     </indexterm>
9288
9289 <synopsis>
9290 <function>xmlcomment</function>(<replaceable>text</replaceable>)
9291 </synopsis>
9292
9293     <para>
9294      The function <function>xmlcomment</function> creates an XML value
9295      containing an XML comment with the specified text as content.
9296      The text cannot contain <quote><literal>--</literal></quote> or end with a
9297      <quote><literal>-</literal></quote> so that the resulting construct is a valid
9298      XML comment.  If the argument is null, the result is null.
9299     </para>
9300
9301     <para>
9302      Example:
9303 <screen><![CDATA[
9304 SELECT xmlcomment('hello');
9305
9306   xmlcomment
9307 --------------
9308  <!--hello-->
9309 ]]></screen>
9310     </para>
9311    </sect3>
9312
9313    <sect3>
9314     <title><literal>xmlconcat</literal></title>
9315
9316     <indexterm>
9317      <primary>xmlconcat</primary>
9318     </indexterm>
9319
9320 <synopsis>
9321 <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
9322 </synopsis>
9323
9324     <para>
9325      The function <function>xmlconcat</function> concatenates a list
9326      of individual XML values to create a single value containing an
9327      XML content fragment.  Null values are omitted; the result is
9328      only null if there are no nonnull arguments.
9329     </para>
9330
9331     <para>
9332      Example:
9333 <screen><![CDATA[
9334 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
9335
9336       xmlconcat
9337 ----------------------
9338  <abc/><bar>foo</bar>
9339 ]]></screen>
9340     </para>
9341
9342     <para>
9343      XML declarations, if present, are combined as follows.  If all
9344      argument values have the same XML version declaration, that
9345      version is used in the result, else no version is used.  If all
9346      argument values have the standalone declaration value
9347      <quote>yes</quote>, then that value is used in the result.  If
9348      all argument values have a standalone declaration value and at
9349      least one is <quote>no</quote>, then that is used in the result.
9350      Else the result will have no standalone declaration.  If the
9351      result is determined to require a standalone declaration but no
9352      version declaration, a version declaration with version 1.0 will
9353      be used because XML requires an XML declaration to contain a
9354      version declaration.  Encoding declarations are ignored and
9355      removed in all cases.
9356     </para>
9357
9358     <para>
9359      Example:
9360 <screen><![CDATA[
9361 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
9362
9363              xmlconcat
9364 -----------------------------------
9365  <?xml version="1.1"?><foo/><bar/>
9366 ]]></screen>
9367     </para>
9368    </sect3>
9369
9370    <sect3>
9371     <title><literal>xmlelement</literal></title>
9372
9373    <indexterm>
9374     <primary>xmlelement</primary>
9375    </indexterm>
9376
9377 <synopsis>
9378 <function>xmlelement</function>(name <replaceable>name</replaceable> <optional>, xmlattributes(<replaceable>value</replaceable> <optional>AS <replaceable>attname</replaceable></optional> <optional>, ... </optional>)</optional> <optional><replaceable>, content, ...</replaceable></optional>)
9379 </synopsis>
9380
9381     <para>
9382      The <function>xmlelement</function> expression produces an XML
9383      element with the given name, attributes, and content.
9384     </para>
9385
9386     <para>
9387      Examples:
9388 <screen><![CDATA[
9389 SELECT xmlelement(name foo);
9390
9391  xmlelement
9392 ------------
9393  <foo/>
9394
9395 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
9396
9397     xmlelement
9398 ------------------
9399  <foo bar="xyz"/>
9400
9401 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
9402
9403              xmlelement
9404 -------------------------------------
9405  <foo bar="2007-01-26">content</foo>
9406 ]]></screen>
9407     </para>
9408
9409     <para>
9410      Element and attribute names that are not valid XML names are
9411      escaped by replacing the offending characters by the sequence
9412      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
9413      <replaceable>HHHH</replaceable> is the character's Unicode
9414      codepoint in hexadecimal notation.  For example:
9415 <screen><![CDATA[
9416 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
9417
9418             xmlelement
9419 ----------------------------------
9420  <foo_x0024_bar a_x0026_b="xyz"/>
9421 ]]></screen>
9422     </para>
9423
9424     <para>
9425      An explicit attribute name need not be specified if the attribute
9426      value is a column reference, in which case the column's name will
9427      be used as the attribute name by default.  In other cases, the
9428      attribute must be given an explicit name.  So this example is
9429      valid:
9430 <screen>
9431 CREATE TABLE test (a xml, b xml);
9432 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
9433 </screen>
9434      But these are not:
9435 <screen>
9436 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
9437 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
9438 </screen>
9439     </para>
9440
9441     <para>
9442      Element content, if specified, will be formatted according to
9443      its data type.  If the content is itself of type <type>xml</type>,
9444      complex XML documents can be constructed.  For example:
9445 <screen><![CDATA[
9446 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
9447                             xmlelement(name abc),
9448                             xmlcomment('test'),
9449                             xmlelement(name xyz));
9450
9451                   xmlelement
9452 ----------------------------------------------
9453  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
9454 ]]></screen>
9455
9456      Content of other types will be formatted into valid XML character
9457      data.  This means in particular that the characters &lt;, &gt;,
9458      and &amp; will be converted to entities.  Binary data (data type
9459      <type>bytea</type>) will be represented in base64 or hex
9460      encoding, depending on the setting of the configuration parameter
9461      <xref linkend="guc-xmlbinary">.  The particular behavior for
9462      individual data types is expected to evolve in order to align the
9463      SQL and PostgreSQL data types with the XML Schema specification,
9464      at which point a more precise description will appear.
9465     </para>
9466    </sect3>
9467
9468    <sect3>
9469     <title><literal>xmlforest</literal></title>
9470
9471    <indexterm>
9472     <primary>xmlforest</primary>
9473    </indexterm>
9474
9475 <synopsis>
9476 <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
9477 </synopsis>
9478
9479     <para>
9480      The <function>xmlforest</function> expression produces an XML
9481      forest (sequence) of elements using the given names and content.
9482     </para>
9483
9484     <para>
9485      Examples:
9486 <screen><![CDATA[
9487 SELECT xmlforest('abc' AS foo, 123 AS bar);
9488
9489           xmlforest
9490 ------------------------------
9491  <foo>abc</foo><bar>123</bar>
9492
9493
9494 SELECT xmlforest(table_name, column_name)
9495 FROM information_schema.columns
9496 WHERE table_schema = 'pg_catalog';
9497
9498                                          xmlforest
9499 -------------------------------------------------------------------------------------------
9500  <table_name>pg_authid</table_name><column_name>rolname</column_name>
9501  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
9502  ...
9503 ]]></screen>
9504
9505      As seen in the second example, the element name can be omitted if
9506      the content value is a column reference, in which case the column
9507      name is used by default.  Otherwise, a name must be specified.
9508     </para>
9509
9510     <para>
9511      Element names that are not valid XML names are escaped as shown
9512      for <function>xmlelement</function> above.  Similarly, content
9513      data is escaped to make valid XML content, unless it is already
9514      of type <type>xml</type>.
9515     </para>
9516
9517     <para>
9518      Note that XML forests are not valid XML documents if they consist
9519      of more than one element, so it might be useful to wrap
9520      <function>xmlforest</function> expressions in
9521      <function>xmlelement</function>.
9522     </para>
9523    </sect3>
9524
9525    <sect3>
9526     <title><literal>xmlpi</literal></title>
9527
9528    <indexterm>
9529     <primary>xmlpi</primary>
9530    </indexterm>
9531
9532 <synopsis>
9533 <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
9534 </synopsis>
9535
9536     <para>
9537      The <function>xmlpi</function> expression creates an XML
9538      processing instruction.  The content, if present, must not
9539      contain the character sequence <literal>?&gt;</literal>.
9540     </para>
9541
9542     <para>
9543      Example:
9544 <screen><![CDATA[
9545 SELECT xmlpi(name php, 'echo "hello world";');
9546
9547             xmlpi
9548 -----------------------------
9549  <?php echo "hello world";?>
9550 ]]></screen>
9551     </para>
9552    </sect3>
9553
9554    <sect3>
9555     <title><literal>xmlroot</literal></title>
9556
9557    <indexterm>
9558     <primary>xmlroot</primary>
9559    </indexterm>
9560
9561 <synopsis>
9562 <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
9563 </synopsis>
9564
9565     <para>
9566      The <function>xmlroot</function> expression alters the properties
9567      of the root node of an XML value.  If a version is specified,
9568      it replaces the value in the root node's version declaration; if a
9569      standalone setting is specified, it replaces the value in the
9570      root node's standalone declaration.
9571     </para>
9572
9573     <para>
9574 <screen><![CDATA[
9575 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
9576                version '1.0', standalone yes);
9577
9578                 xmlroot
9579 ----------------------------------------
9580  <?xml version="1.0" standalone="yes"?>
9581  <content>abc</content>
9582 ]]></screen>
9583     </para>
9584    </sect3>
9585
9586    <sect3 id="functions-xml-xmlagg">
9587     <title><literal>xmlagg</literal></title>
9588
9589     <indexterm>
9590      <primary>xmlagg</primary>
9591     </indexterm>
9592
9593 <synopsis>
9594 <function>xmlagg</function>(<replaceable>xml</replaceable>)
9595 </synopsis>
9596
9597     <para>
9598      The function <function>xmlagg</function> is, unlike the other
9599      functions described here, an aggregate function.  It concatenates the
9600      input values to the aggregate function call,
9601      much like <function>xmlconcat</function> does, except that concatenation
9602      occurs across rows rather than across expressions in a single row.
9603      See <xref linkend="functions-aggregate"> for additional information
9604      about aggregate functions.
9605     </para>
9606
9607     <para>
9608      Example:
9609 <screen><![CDATA[
9610 CREATE TABLE test (y int, x xml);
9611 INSERT INTO test VALUES (1, '<foo>abc</foo>');
9612 INSERT INTO test VALUES (2, '<bar/>');
9613 SELECT xmlagg(x) FROM test;
9614         xmlagg
9615 ----------------------
9616  <foo>abc</foo><bar/>
9617 ]]></screen>
9618     </para>
9619
9620     <para>
9621      To determine the order of the concatenation, an <literal>ORDER BY</>
9622      clause may be added to the aggregate call as described in
9623      <xref linkend="syntax-aggregates">. For example:
9624
9625 <screen><![CDATA[
9626 SELECT xmlagg(x ORDER BY y DESC) FROM test;
9627         xmlagg
9628 ----------------------
9629  <bar/><foo>abc</foo>
9630 ]]></screen>
9631     </para>
9632
9633     <para>
9634      The following non-standard approach used to be recommended
9635      in previous versions, and may still be useful in specific
9636      cases:
9637
9638 <screen><![CDATA[
9639 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
9640         xmlagg
9641 ----------------------
9642  <bar/><foo>abc</foo>
9643 ]]></screen>
9644     </para>
9645    </sect3>
9646    </sect2>
9647
9648    <sect2 id="functions-xml-predicates">
9649     <title>XML Predicates</title>
9650
9651     <para>
9652      The expressions described in this section check properties
9653      of <type>xml</type> values.
9654     </para>
9655
9656    <sect3>
9657     <title><literal>IS DOCUMENT</literal></title>
9658
9659     <indexterm>
9660      <primary>IS DOCUMENT</primary>
9661     </indexterm>
9662
9663 <synopsis>
9664 <replaceable>xml</replaceable> IS DOCUMENT
9665 </synopsis>
9666
9667     <para>
9668      The expression <literal>IS DOCUMENT</literal> returns true if the
9669      argument XML value is a proper XML document, false if it is not
9670      (that is, it is a content fragment), or null if the argument is
9671      null.  See <xref linkend="datatype-xml"> about the difference
9672      between documents and content fragments.
9673     </para>
9674    </sect3>
9675
9676    <sect3 id="xml-exists">
9677     <title><literal>XMLEXISTS</literal></title>
9678
9679     <indexterm>
9680      <primary>XMLEXISTS</primary>
9681     </indexterm>
9682
9683 <synopsis>
9684 <function>XMLEXISTS</function>(<replaceable>text</replaceable> PASSING <optional>BY REF</optional> <replaceable>xml</replaceable> <optional>BY REF</optional>)
9685 </synopsis>
9686
9687     <para>
9688      The function <function>xmlexists</function> returns true if the
9689      XPath expression in the first argument returns any nodes, and
9690      false otherwise.  (If either argument is null, the result is
9691      null.)
9692     </para>
9693
9694     <para>
9695      Example:
9696      <screen><![CDATA[
9697 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY REF '<towns><town>Toronto</town><town>Ottawa</town></towns>');
9698
9699  xmlexists
9700 ------------
9701  t
9702 (1 row)
9703 ]]></screen>
9704     </para>
9705
9706     <para>
9707      The <literal>BY REF</literal> clauses have no effect in
9708      PostgreSQL, but are allowed for SQL conformance and compatibility
9709      with other implementations.  Per SQL standard, the
9710      first <literal>BY REF</literal> is required, the second is
9711      optional.  Also note that the SQL standard specifies
9712      the <function>xmlexists</function> construct to take an XQuery
9713      expression as first argument, but PostgreSQL currently only
9714      supports XPath, which is a subset of XQuery.
9715     </para>
9716    </sect3>
9717
9718    <sect3 id="xml-is-well-formed">
9719     <title><literal>xml_is_well_formed</literal></title>
9720
9721     <indexterm>
9722      <primary>xml_is_well_formed</primary>
9723     </indexterm>
9724
9725     <indexterm>
9726      <primary>xml_is_well_formed_document</primary>
9727     </indexterm>
9728
9729     <indexterm>
9730      <primary>xml_is_well_formed_content</primary>
9731     </indexterm>
9732
9733 <synopsis>
9734 <function>xml_is_well_formed</function>(<replaceable>text</replaceable>)
9735 <function>xml_is_well_formed_document</function>(<replaceable>text</replaceable>)
9736 <function>xml_is_well_formed_content</function>(<replaceable>text</replaceable>)
9737 </synopsis>
9738
9739     <para>
9740      These functions check whether a <type>text</> string is well-formed XML,
9741      returning a Boolean result.
9742      <function>xml_is_well_formed_document</function> checks for a well-formed
9743      document, while <function>xml_is_well_formed_content</function> checks
9744      for well-formed content.  <function>xml_is_well_formed</function> does
9745      the former if the <xref linkend="guc-xmloption"> configuration
9746      parameter is set to <literal>DOCUMENT</>, or the latter if it is set to
9747      <literal>CONTENT</>.  This means that
9748      <function>xml_is_well_formed</function> is useful for seeing whether
9749      a simple cast to type <type>xml</> will succeed, whereas the other two
9750      functions are useful for seeing whether the corresponding variants of
9751      <function>XMLPARSE</> will succeed.
9752     </para>
9753
9754     <para>
9755      Examples:
9756
9757 <screen><![CDATA[
9758 SET xmloption TO DOCUMENT;
9759 SELECT xml_is_well_formed('<>');
9760  xml_is_well_formed 
9761 --------------------
9762  f
9763 (1 row)
9764
9765 SELECT xml_is_well_formed('<abc/>');
9766  xml_is_well_formed 
9767 --------------------
9768  t
9769 (1 row)
9770
9771 SET xmloption TO CONTENT;
9772 SELECT xml_is_well_formed('abc');
9773  xml_is_well_formed 
9774 --------------------
9775  t
9776 (1 row)
9777
9778 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
9779  xml_is_well_formed_document 
9780 -----------------------------
9781  t
9782 (1 row)
9783
9784 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
9785  xml_is_well_formed_document 
9786 -----------------------------
9787  f
9788 (1 row)
9789 ]]></screen>
9790
9791      The last example shows that the checks include whether
9792      namespaces are correctly matched.
9793     </para>
9794    </sect3>
9795   </sect2>
9796
9797   <sect2 id="functions-xml-processing">
9798    <title>Processing XML</title>
9799
9800    <indexterm>
9801     <primary>XPath</primary>
9802    </indexterm>
9803
9804    <para>
9805     To process values of data type <type>xml</type>, PostgreSQL offers
9806     the functions <function>xpath</function> and
9807     <function>xpath_exists</function>, which evaluate XPath 1.0
9808     expressions.
9809    </para>
9810
9811 <synopsis>
9812 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9813 </synopsis>
9814
9815    <para>
9816     The function <function>xpath</function> evaluates the XPath
9817     expression <replaceable>xpath</replaceable> (a <type>text</> value)
9818     against the XML value
9819     <replaceable>xml</replaceable>.  It returns an array of XML values
9820     corresponding to the node set produced by the XPath expression.
9821     If the XPath expression returns a scalar value rather than a node set,
9822     a single-element array is returned.
9823    </para>
9824
9825   <para>
9826     The second argument must be a well formed XML document. In particular,
9827     it must have a single root node element.
9828   </para>
9829
9830    <para>
9831     The optional third argument of the function is an array of namespace
9832     mappings.  This array should be a two-dimensional <type>text</> array with
9833     the length of the second axis being equal to 2 (i.e., it should be an
9834     array of arrays, each of which consists of exactly 2 elements).
9835     The first element of each array entry is the namespace name (alias), the
9836     second the namespace URI. It is not required that aliases provided in
9837     this array be the same as those being used in the XML document itself (in
9838     other words, both in the XML document and in the <function>xpath</function>
9839     function context, aliases are <emphasis>local</>).
9840    </para>
9841
9842    <para>
9843     Example:
9844 <screen><![CDATA[
9845 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9846              ARRAY[ARRAY['my', 'http://example.com']]);
9847
9848  xpath  
9849 --------
9850  {test}
9851 (1 row)
9852 ]]></screen>
9853    </para>
9854
9855    <para>
9856     To deal with default (anonymous) namespaces, do something like this:
9857 <screen><![CDATA[
9858 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
9859              ARRAY[ARRAY['mydefns', 'http://example.com']]);
9860
9861  xpath
9862 --------
9863  {test}
9864 (1 row)
9865 ]]></screen>
9866    </para>
9867
9868    <indexterm>
9869     <primary>xpath_exists</primary>
9870    </indexterm>
9871
9872 <synopsis>
9873 <function>xpath_exists</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9874 </synopsis>
9875
9876    <para>
9877     The function <function>xpath_exists</function> is a specialized form
9878     of the <function>xpath</function> function.  Instead of returning the
9879     individual XML values that satisfy the XPath, this function returns a
9880     Boolean indicating whether the query was satisfied or not.  This
9881     function is equivalent to the standard <literal>XMLEXISTS</> predicate,
9882     except that it also offers support for a namespace mapping argument.
9883    </para>
9884
9885    <para>
9886     Example:
9887 <screen><![CDATA[
9888 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9889                      ARRAY[ARRAY['my', 'http://example.com']]);
9890
9891  xpath_exists  
9892 --------------
9893  t
9894 (1 row)
9895 ]]></screen>
9896    </para>
9897   </sect2>
9898
9899   <sect2 id="functions-xml-mapping">
9900    <title>Mapping Tables to XML</title>
9901
9902    <indexterm zone="functions-xml-mapping">
9903     <primary>XML export</primary>
9904    </indexterm>
9905
9906    <para>
9907     The following functions map the contents of relational tables to
9908     XML values.  They can be thought of as XML export functionality:
9909 <synopsis>
9910 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9911 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
9912 cursor_to_xml(cursor refcursor, count int, nulls boolean,
9913               tableforest boolean, targetns text)
9914 </synopsis>
9915     The return type of each function is <type>xml</type>.
9916    </para>
9917
9918    <para>
9919     <function>table_to_xml</function> maps the content of the named
9920     table, passed as parameter <parameter>tbl</parameter>.  The
9921     <type>regclass</type> type accepts strings identifying tables using the
9922     usual notation, including optional schema qualifications and
9923     double quotes.  <function>query_to_xml</function> executes the
9924     query whose text is passed as parameter
9925     <parameter>query</parameter> and maps the result set.
9926     <function>cursor_to_xml</function> fetches the indicated number of
9927     rows from the cursor specified by the parameter
9928     <parameter>cursor</parameter>.  This variant is recommended if
9929     large tables have to be mapped, because the result value is built
9930     up in memory by each function.
9931    </para>
9932
9933    <para>
9934     If <parameter>tableforest</parameter> is false, then the resulting
9935     XML document looks like this:
9936 <screen><![CDATA[
9937 <tablename>
9938   <row>
9939     <columnname1>data</columnname1>
9940     <columnname2>data</columnname2>
9941   </row>
9942
9943   <row>
9944     ...
9945   </row>
9946
9947   ...
9948 </tablename>
9949 ]]></screen>
9950
9951     If <parameter>tableforest</parameter> is true, the result is an
9952     XML content fragment that looks like this:
9953 <screen><![CDATA[
9954 <tablename>
9955   <columnname1>data</columnname1>
9956   <columnname2>data</columnname2>
9957 </tablename>
9958
9959 <tablename>
9960   ...
9961 </tablename>
9962
9963 ...
9964 ]]></screen>
9965
9966     If no table name is available, that is, when mapping a query or a
9967     cursor, the string <literal>table</literal> is used in the first
9968     format, <literal>row</literal> in the second format.
9969    </para>
9970
9971    <para>
9972     The choice between these formats is up to the user.  The first
9973     format is a proper XML document, which will be important in many
9974     applications.  The second format tends to be more useful in the
9975     <function>cursor_to_xml</function> function if the result values are to be
9976     reassembled into one document later on.  The functions for
9977     producing XML content discussed above, in particular
9978     <function>xmlelement</function>, can be used to alter the results
9979     to taste.
9980    </para>
9981
9982    <para>
9983     The data values are mapped in the same way as described for the
9984     function <function>xmlelement</function> above.
9985    </para>
9986
9987    <para>
9988     The parameter <parameter>nulls</parameter> determines whether null
9989     values should be included in the output.  If true, null values in
9990     columns are represented as:
9991 <screen><![CDATA[
9992 <columnname xsi:nil="true"/>
9993 ]]></screen>
9994     where <literal>xsi</literal> is the XML namespace prefix for XML
9995     Schema Instance.  An appropriate namespace declaration will be
9996     added to the result value.  If false, columns containing null
9997     values are simply omitted from the output.
9998    </para>
9999
10000    <para>
10001     The parameter <parameter>targetns</parameter> specifies the
10002     desired XML namespace of the result.  If no particular namespace
10003     is wanted, an empty string should be passed.
10004    </para>
10005
10006    <para>
10007     The following functions return XML Schema documents describing the
10008     mappings performed by the corresponding functions above:
10009 <synopsis>
10010 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
10011 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
10012 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
10013 </synopsis>
10014     It is essential that the same parameters are passed in order to
10015     obtain matching XML data mappings and XML Schema documents.
10016    </para>
10017
10018    <para>
10019     The following functions produce XML data mappings and the
10020     corresponding XML Schema in one document (or forest), linked
10021     together.  They can be useful where self-contained and
10022     self-describing results are wanted:
10023 <synopsis>
10024 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
10025 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
10026 </synopsis>
10027    </para>
10028
10029    <para>
10030     In addition, the following functions are available to produce
10031     analogous mappings of entire schemas or the entire current
10032     database:
10033 <synopsis>
10034 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
10035 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
10036 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
10037
10038 database_to_xml(nulls boolean, tableforest boolean, targetns text)
10039 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
10040 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
10041 </synopsis>
10042
10043     Note that these potentially produce a lot of data, which needs to
10044     be built up in memory.  When requesting content mappings of large
10045     schemas or databases, it might be worthwhile to consider mapping the
10046     tables separately instead, possibly even through a cursor.
10047    </para>
10048
10049    <para>
10050     The result of a schema content mapping looks like this:
10051
10052 <screen><![CDATA[
10053 <schemaname>
10054
10055 table1-mapping
10056
10057 table2-mapping
10058
10059 ...
10060
10061 </schemaname>]]></screen>
10062
10063     where the format of a table mapping depends on the
10064     <parameter>tableforest</parameter> parameter as explained above.
10065    </para>
10066
10067    <para>
10068     The result of a database content mapping looks like this:
10069
10070 <screen><![CDATA[
10071 <dbname>
10072
10073 <schema1name>
10074   ...
10075 </schema1name>
10076
10077 <schema2name>
10078   ...
10079 </schema2name>
10080
10081 ...
10082
10083 </dbname>]]></screen>
10084
10085     where the schema mapping is as above.
10086    </para>
10087
10088    <para>
10089     As an example of using the output produced by these functions,
10090     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
10091     converts the output of
10092     <function>table_to_xml_and_xmlschema</function> to an HTML
10093     document containing a tabular rendition of the table data.  In a
10094     similar manner, the results from these functions can be
10095     converted into other XML-based formats.
10096    </para>
10097
10098    <figure id="xslt-xml-html">
10099     <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
10100 <programlisting><![CDATA[
10101 <?xml version="1.0"?>
10102 <xsl:stylesheet version="1.0"
10103     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
10104     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
10105     xmlns="http://www.w3.org/1999/xhtml"
10106 >
10107
10108   <xsl:output method="xml"
10109       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
10110       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
10111       indent="yes"/>
10112
10113   <xsl:template match="/*">
10114     <xsl:variable name="schema" select="//xsd:schema"/>
10115     <xsl:variable name="tabletypename"
10116                   select="$schema/xsd:element[@name=name(current())]/@type"/>
10117     <xsl:variable name="rowtypename"
10118                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
10119
10120     <html>
10121       <head>
10122         <title><xsl:value-of select="name(current())"/></title>
10123       </head>
10124       <body>
10125         <table>
10126           <tr>
10127             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
10128               <th><xsl:value-of select="."/></th>
10129             </xsl:for-each>
10130           </tr>
10131
10132           <xsl:for-each select="row">
10133             <tr>
10134               <xsl:for-each select="*">
10135                 <td><xsl:value-of select="."/></td>
10136               </xsl:for-each>
10137             </tr>
10138           </xsl:for-each>
10139         </table>
10140       </body>
10141     </html>
10142   </xsl:template>
10143
10144 </xsl:stylesheet>
10145 ]]></programlisting>
10146    </figure>
10147   </sect2>
10148  </sect1>
10149
10150  <sect1 id="functions-json">
10151   <title>JSON Functions and Operators</title>
10152
10153   <indexterm zone="functions-json">
10154     <primary>JSON</primary>
10155     <secondary>functions and operators</secondary>
10156   </indexterm>
10157
10158    <para>
10159    <xref linkend="functions-json-op-table"> shows the operators that
10160    are available for use with the two JSON data types (see <xref
10161    linkend="datatype-json">).
10162   </para>
10163
10164   <table id="functions-json-op-table">
10165      <title><type>json</> and <type>jsonb</> Operators</title>
10166      <tgroup cols="5">
10167       <thead>
10168        <row>
10169         <entry>Operator</entry>
10170         <entry>Right Operand Type</entry>
10171         <entry>Description</entry>
10172         <entry>Example</entry>
10173         <entry>Example Result</entry>
10174        </row>
10175       </thead>
10176       <tbody>
10177        <row>
10178         <entry><literal>-&gt;</literal></entry>
10179         <entry><type>int</type></entry>
10180         <entry>Get JSON array element (indexed from zero)</entry>
10181         <entry><literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json-&gt;2</literal></entry>
10182         <entry><literal>{"c":"baz"}</literal></entry>
10183        </row>
10184        <row>
10185         <entry><literal>-&gt;</literal></entry>
10186         <entry><type>text</type></entry>
10187         <entry>Get JSON object field by key</entry>
10188         <entry><literal>'{"a": {"b":"foo"}}'::json-&gt;'a'</literal></entry>
10189         <entry><literal>{"b":"foo"}</literal></entry>
10190        </row>
10191         <row>
10192         <entry><literal>-&gt;&gt;</literal></entry>
10193         <entry><type>int</type></entry>
10194         <entry>Get JSON array element as <type>text</></entry>
10195         <entry><literal>'[1,2,3]'::json-&gt;&gt;2</literal></entry>
10196         <entry><literal>3</literal></entry>
10197        </row>
10198        <row>
10199         <entry><literal>-&gt;&gt;</literal></entry>
10200         <entry><type>text</type></entry>
10201         <entry>Get JSON object field as <type>text</></entry>
10202         <entry><literal>'{"a":1,"b":2}'::json-&gt;&gt;'b'</literal></entry>
10203         <entry><literal>2</literal></entry>
10204        </row>
10205        <row>
10206         <entry><literal>#&gt;</literal></entry>
10207         <entry><type>text[]</type></entry>
10208         <entry>Get JSON object at specified path</entry>
10209         <entry><literal>'{"a": {"b":{"c": "foo"}}}'::json#&gt;'{a,b}'</literal></entry>
10210         <entry><literal>{"c": "foo"}</literal></entry>
10211        </row>
10212        <row>
10213         <entry><literal>#&gt;&gt;</literal></entry>
10214         <entry><type>text[]</type></entry>
10215         <entry>Get JSON object at specified path as <type>text</></entry>
10216         <entry><literal>'{"a":[1,2,3],"b":[4,5,6]}'::json#&gt;&gt;'{a,2}'</literal></entry>
10217         <entry><literal>3</literal></entry>
10218        </row>
10219       </tbody>
10220      </tgroup>
10221    </table>
10222
10223   <note>
10224    <para>
10225     There are parallel variants of these operators for both the
10226     <type>json</type> and <type>jsonb</type> types.
10227     The field/element/path extraction operators
10228     return the same type as their left-hand input (either <type>json</type>
10229     or <type>jsonb</type>), except for those specified as
10230     returning <type>text</>, which coerce the value to text.
10231     The field/element/path extraction operators return NULL, rather than
10232     failing, if the JSON input does not have the right structure to match
10233     the request; for example if no such element exists.
10234    </para>
10235   </note>
10236   <para>
10237    The standard comparison operators shown in  <xref
10238    linkend="functions-comparison-table"> are available for
10239    <type>jsonb</type>, but not for <type>json</type>. They follow the
10240    ordering rules for B-tree operations outlined at <xref
10241    linkend="json-indexing">.
10242   </para>
10243   <para>
10244    Some further operators also exist only for <type>jsonb</type>, as shown
10245    in <xref linkend="functions-jsonb-op-table">.
10246    Many of these operators can be indexed by
10247    <type>jsonb</> operator classes.  For a full description of
10248    <type>jsonb</> containment and existence semantics, see <xref
10249    linkend="json-containment">.  <xref linkend="json-indexing">
10250    describes how these operators can be used to effectively index
10251    <type>jsonb</> data.
10252   </para>
10253   <table id="functions-jsonb-op-table">
10254      <title>Additional <type>jsonb</> Operators</title>
10255      <tgroup cols="4">
10256       <thead>
10257        <row>
10258         <entry>Operator</entry>
10259         <entry>Right Operand Type</entry>
10260         <entry>Description</entry>
10261         <entry>Example</entry>
10262        </row>
10263       </thead>
10264       <tbody>
10265        <row>
10266         <entry><literal>@&gt;</literal></entry>
10267         <entry><type>jsonb</type></entry>
10268         <entry>Does the left JSON value contain within it the right value?</entry>
10269         <entry><literal>'{"a":1, "b":2}'::jsonb &#64;&gt; '{"b":2}'::jsonb</literal></entry>
10270        </row>
10271        <row>
10272         <entry><literal>&lt;@</literal></entry>
10273         <entry><type>jsonb</type></entry>
10274         <entry>Is the left JSON value contained within the right value?</entry>
10275         <entry><literal>'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</literal></entry>
10276        </row>
10277        <row>
10278         <entry><literal>?</literal></entry>
10279         <entry><type>text</type></entry>
10280         <entry>Does the key/element <emphasis>string</emphasis> exist within
10281         the JSON value?</entry>
10282         <entry><literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal></entry>
10283        </row>
10284        <row>
10285         <entry><literal>?|</literal></entry>
10286         <entry><type>text[]</type></entry>
10287         <entry>Do any of these key/element <emphasis>strings</emphasis> exist?</entry>
10288         <entry><literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'c']</literal></entry>
10289        </row>
10290        <row>
10291         <entry><literal>?&amp;</literal></entry>
10292         <entry><type>text[]</type></entry>
10293         <entry>Do all of these key/element <emphasis>strings</emphasis> exist?</entry>
10294         <entry><literal>'["a", "b"]'::jsonb ?&amp; array['a', 'b']</literal></entry>
10295        </row>
10296        <row>
10297         <entry><literal>||</literal></entry>
10298         <entry><type>jsonb</type></entry>
10299         <entry>Concatentate two jsonb values into a new jsonb value</entry>
10300         <entry><literal>'["a", "b"]'::jsonb || '["c", "d"]'::jsonb</literal></entry>
10301        </row>
10302        <row>
10303         <entry><literal>-</literal></entry>
10304         <entry><type>text</type></entry>
10305         <entry>Delete the field with a specified key, or element with this
10306         value</entry>
10307         <entry><literal>'{"a": "b"}'::jsonb - 'a' </literal></entry>
10308        </row>
10309        <row>
10310         <entry><literal>-</literal></entry>
10311         <entry><type>integer</type></entry>
10312         <entry>Delete the field or element with specified index (Negative
10313         integers count from the end)</entry>
10314         <entry><literal>'["a", "b"]'::jsonb - 1 </literal></entry>
10315        </row>
10316        <row>
10317         <entry><literal>-</literal></entry>
10318         <entry><type>text[]</type></entry>
10319         <entry>Delete the field or element with specified path</entry>
10320         <entry><literal>'["a", {"b":1}]'::jsonb - '{1,b}'::text[] </literal></entry>
10321        </row>
10322       </tbody>
10323      </tgroup>
10324    </table>
10325
10326   <para>
10327    <xref linkend="functions-json-creation-table"> shows the functions that are
10328    available for creating <type>json</type> and <type>jsonb</type> values.
10329    (There are no equivalent functions for <type>jsonb</>, of the <literal>row_to_json</>
10330    and <literal>array_to_json</> functions. However, the <literal>to_jsonb</>
10331    function supplies much the same functionality as these functions would.)
10332   </para>
10333
10334   <indexterm>
10335    <primary>to_json</primary>
10336   </indexterm>
10337   <indexterm>
10338    <primary>array_to_json</primary>
10339   </indexterm>
10340   <indexterm>
10341    <primary>row_to_json</primary>
10342   </indexterm>
10343   <indexterm>
10344    <primary>json_build_array</primary>
10345   </indexterm>
10346   <indexterm>
10347    <primary>json_build_object</primary>
10348   </indexterm>
10349   <indexterm>
10350    <primary>json_object</primary>
10351   </indexterm>
10352   <indexterm>
10353    <primary>to_jsonb</primary>
10354   </indexterm>
10355   <indexterm>
10356    <primary>jsonb_build_array</primary>
10357   </indexterm>
10358   <indexterm>
10359    <primary>jsonb_build_object</primary>
10360   </indexterm>
10361   <indexterm>
10362    <primary>jsonb_object</primary>
10363   </indexterm>
10364
10365   <table id="functions-json-creation-table">
10366     <title>JSON Creation Functions</title>
10367     <tgroup cols="4">
10368      <thead>
10369       <row>
10370        <entry>Function</entry>
10371        <entry>Description</entry>
10372        <entry>Example</entry>
10373        <entry>Example Result</entry>
10374       </row>
10375      </thead>
10376      <tbody>
10377       <row>
10378        <entry><para><literal>to_json(anyelement)</literal>
10379           </para><para><literal>to_jsonb(anyelement)</literal>
10380        </para></entry>
10381        <entry>
10382          Returns the value as <type>json</> or <type>jsonb</>.
10383          Arrays and composites are converted
10384          (recursively) to arrays and objects; otherwise, if there is a cast
10385          from the type to <type>json</type>, the cast function will be used to
10386          perform the conversion; otherwise, a scalar value is produced.
10387          For any scalar type other than a number, a Boolean, or a null value,
10388          the text representation will be used, in such a fashion that it is a
10389          valid <type>json</> or <type>jsonb</> value.
10390        </entry>
10391        <entry><literal>to_json('Fred said "Hi."'::text)</literal></entry>
10392        <entry><literal>"Fred said \"Hi.\""</literal></entry>
10393       </row>
10394       <row>
10395        <entry>
10396          <literal>array_to_json(anyarray [, pretty_bool])</literal>
10397        </entry>
10398        <entry>
10399          Returns the array as a JSON array. A PostgreSQL multidimensional array
10400          becomes a JSON array of arrays. Line feeds will be added between
10401          dimension-1 elements if <parameter>pretty_bool</parameter> is true.
10402        </entry>
10403        <entry><literal>array_to_json('{{1,5},{99,100}}'::int[])</literal></entry>
10404        <entry><literal>[[1,5],[99,100]]</literal></entry>
10405       </row>
10406       <row>
10407        <entry>
10408          <literal>row_to_json(record [, pretty_bool])</literal>
10409        </entry>
10410        <entry>
10411          Returns the row as a JSON object. Line feeds will be added between
10412          level-1 elements if <parameter>pretty_bool</parameter> is true.
10413        </entry>
10414        <entry><literal>row_to_json(row(1,'foo'))</literal></entry>
10415        <entry><literal>{"f1":1,"f2":"foo"}</literal></entry>
10416       </row>
10417       <row>
10418        <entry><para><literal>json_build_array(VARIADIC "any")</literal>
10419           </para><para><literal>jsonb_build_array(VARIADIC "any")</literal>
10420        </para></entry>
10421        <entry>
10422          Builds a possibly-heterogeneously-typed JSON array out of a variadic
10423          argument list.
10424        </entry>
10425        <entry><literal>json_build_array(1,2,'3',4,5)</literal></entry>
10426        <entry><literal>[1, 2, "3", 4, 5]</literal></entry>
10427       </row>
10428       <row>
10429        <entry><para><literal>json_build_object(VARIADIC "any")</literal>
10430           </para><para><literal>jsonb_build_object(VARIADIC "any")</literal>
10431        </para></entry>
10432        <entry>
10433          Builds a JSON object out of a variadic argument list.  By
10434          convention, the argument list consists of alternating
10435          keys and values.
10436        </entry>
10437        <entry><literal>json_build_object('foo',1,'bar',2)</literal></entry>
10438        <entry><literal>{"foo": 1, "bar": 2}</literal></entry>
10439       </row>
10440       <row>
10441        <entry><para><literal>json_object(text[])</literal>
10442           </para><para><literal>jsonb_object(text[])</literal>
10443        </para></entry>
10444        <entry>
10445          Builds a JSON object out of a text array.  The array must have either
10446          exactly one dimension with an even number of members, in which case
10447          they are taken as alternating key/value pairs, or two dimensions
10448          such that each inner array has exactly two elements, which
10449          are taken as a key/value pair.
10450        </entry>
10451        <entry><para><literal>json_object('{a, 1, b, "def", c, 3.5}')</></para>
10452         <para><literal>json_object('{{a, 1},{b, "def"},{c, 3.5}}')</></para></entry>
10453        <entry><literal>{"a": "1", "b": "def", "c": "3.5"}</literal></entry>
10454       </row>
10455       <row>
10456        <entry><para><literal>json_object(keys text[], values text[])</literal>
10457           </para><para><literal>jsonb_object(keys text[], values text[])</literal>
10458        </para></entry>
10459        <entry>
10460          This form of <function>json_object</> takes keys and values pairwise from two separate
10461          arrays. In all other respects it is identical to the one-argument form.
10462        </entry>
10463        <entry><literal>json_object('{a, b}', '{1,2}')</literal></entry>
10464        <entry><literal>{"a": "1", "b": "2"}</literal></entry>
10465       </row>
10466      </tbody>
10467     </tgroup>
10468    </table>
10469
10470   <note>
10471     <para>
10472      <function>array_to_json</> and <function>row_to_json</> have the same
10473      behavior as <function>to_json</> except for offering a pretty-printing
10474      option.  The behavior described for <function>to_json</> likewise applies
10475      to each individual value converted by the other JSON creation functions.
10476     </para>
10477   </note>
10478
10479   <note>
10480     <para>
10481      The <xref linkend="hstore"> extension has a cast
10482      from <type>hstore</type> to <type>json</type>, so that
10483      <type>hstore</type> values converted via the JSON creation functions
10484      will be represented as JSON objects, not as primitive string values.
10485     </para>
10486   </note>
10487
10488   <para>
10489    <xref linkend="functions-json-processing-table"> shows the functions that
10490    are available for processing <type>json</type> and <type>jsonb</type> values.
10491   </para>
10492
10493   <indexterm>
10494    <primary>json_array_length</primary>
10495   </indexterm>
10496   <indexterm>
10497    <primary>jsonb_array_length</primary>
10498   </indexterm>
10499   <indexterm>
10500    <primary>json_each</primary>
10501   </indexterm>
10502   <indexterm>
10503    <primary>jsonb_each</primary>
10504   </indexterm>
10505   <indexterm>
10506    <primary>json_each_text</primary>
10507   </indexterm>
10508   <indexterm>
10509    <primary>jsonb_each_text</primary>
10510   </indexterm>
10511   <indexterm>
10512    <primary>json_extract_path</primary>
10513   </indexterm>
10514   <indexterm>
10515    <primary>jsonb_extract_path</primary>
10516   </indexterm>
10517   <indexterm>
10518    <primary>json_extract_path_text</primary>
10519   </indexterm>
10520   <indexterm>
10521    <primary>jsonb_extract_path_text</primary>
10522   </indexterm>
10523   <indexterm>
10524    <primary>json_object_keys</primary>
10525   </indexterm>
10526   <indexterm>
10527    <primary>jsonb_object_keys</primary>
10528   </indexterm>
10529   <indexterm>
10530    <primary>json_populate_record</primary>
10531   </indexterm>
10532   <indexterm>
10533    <primary>jsonb_populate_record</primary>
10534   </indexterm>
10535   <indexterm>
10536    <primary>json_populate_recordset</primary>
10537   </indexterm>
10538   <indexterm>
10539    <primary>jsonb_populate_recordset</primary>
10540   </indexterm>
10541   <indexterm>
10542    <primary>json_array_elements</primary>
10543   </indexterm>
10544   <indexterm>
10545    <primary>jsonb_array_elements</primary>
10546   </indexterm>
10547   <indexterm>
10548    <primary>json_array_elements_text</primary>
10549   </indexterm>
10550   <indexterm>
10551    <primary>jsonb_array_elements_text</primary>
10552   </indexterm>
10553   <indexterm>
10554    <primary>json_typeof</primary>
10555   </indexterm>
10556   <indexterm>
10557    <primary>jsonb_typeof</primary>
10558   </indexterm>
10559   <indexterm>
10560    <primary>json_to_record</primary>
10561   </indexterm>
10562   <indexterm>
10563    <primary>jsonb_to_record</primary>
10564   </indexterm>
10565   <indexterm>
10566    <primary>json_to_recordset</primary>
10567   </indexterm>
10568   <indexterm>
10569    <primary>jsonb_to_recordset</primary>
10570   </indexterm>
10571   <indexterm>
10572    <primary>json_strip_nulls</primary>
10573   </indexterm>
10574   <indexterm>
10575    <primary>jsonb_strip_nulls</primary>
10576   </indexterm>
10577
10578   <table id="functions-json-processing-table">
10579     <title>JSON Processing Functions</title>
10580     <tgroup cols="5">
10581      <thead>
10582       <row>
10583        <entry>Function</entry>
10584        <entry>Return Type</entry>
10585        <entry>Description</entry>
10586        <entry>Example</entry>
10587        <entry>Example Result</entry>
10588       </row>
10589      </thead>
10590      <tbody>
10591       <row>
10592        <entry><para><literal>json_array_length(json)</literal>
10593          </para><para><literal>jsonb_array_length(jsonb)</literal>
10594        </para></entry>
10595        <entry><type>int</type></entry>
10596        <entry>
10597          Returns the number of elements in the outermost JSON array.
10598        </entry>
10599        <entry><literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal></entry>
10600        <entry><literal>5</literal></entry>
10601       </row>
10602       <row>
10603        <entry><para><literal>json_each(json)</literal>
10604          </para><para><literal>jsonb_each(jsonb)</literal>
10605        </para></entry>
10606        <entry><para><literal>setof key text, value json</literal>
10607          </para><para><literal>setof key text, value jsonb</literal>
10608        </para></entry>
10609        <entry>
10610          Expands the outermost JSON object into a set of key/value pairs.
10611        </entry>
10612        <entry><literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal></entry>
10613        <entry>
10614 <programlisting>
10615  key | value
10616 -----+-------
10617  a   | "foo"
10618  b   | "bar"
10619 </programlisting>
10620        </entry>
10621       </row>
10622       <row>
10623        <entry><para><literal>json_each_text(json)</literal>
10624          </para><para><literal>jsonb_each_text(jsonb)</literal>
10625        </para></entry>
10626        <entry><type>setof key text, value text</type></entry>
10627        <entry>
10628          Expands the outermost JSON object into a set of key/value pairs. The
10629          returned values will be of type <type>text</>.
10630        </entry>
10631        <entry><literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal></entry>
10632        <entry>
10633 <programlisting>
10634  key | value
10635 -----+-------
10636  a   | foo
10637  b   | bar
10638 </programlisting>
10639        </entry>
10640       </row>
10641       <row>
10642        <entry><para><literal>json_extract_path(from_json json, VARIADIC path_elems text[])</literal>
10643         </para><para><literal>jsonb_extract_path(from_json jsonb, VARIADIC path_elems text[])</literal>
10644        </para></entry>
10645        <entry><para><type>json</type></para><para><type>jsonb</type>
10646        </para></entry>
10647        <entry>
10648          Returns JSON value pointed to by <replaceable>path_elems</replaceable>
10649          (equivalent to <literal>#&gt;</literal> operator).
10650        </entry>
10651        <entry><literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</literal></entry>
10652        <entry><literal>{"f5":99,"f6":"foo"}</literal></entry>
10653       </row>
10654       <row>
10655        <entry><para><literal>json_extract_path_text(from_json json, VARIADIC path_elems text[])</literal>
10656          </para><para><literal>jsonb_extract_path_text(from_json jsonb, VARIADIC path_elems text[])</literal>
10657        </para></entry>
10658        <entry><type>text</type></entry>
10659        <entry>
10660          Returns JSON value pointed to by <replaceable>path_elems</replaceable>
10661          as <type>text</>
10662          (equivalent to <literal>#&gt;&gt;</literal> operator).
10663        </entry>
10664        <entry><literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</literal></entry>
10665        <entry><literal>foo</literal></entry>
10666       </row>
10667       <row>
10668        <entry><para><literal>json_object_keys(json)</literal>
10669          </para><para><literal>jsonb_object_keys(jsonb)</literal>
10670        </para></entry>
10671        <entry><type>setof text</type></entry>
10672        <entry>
10673           Returns set of keys in the outermost JSON object.
10674        </entry>
10675        <entry><literal>json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal></entry>
10676        <entry>
10677 <programlisting>
10678  json_object_keys
10679 ------------------
10680  f1
10681  f2
10682 </programlisting>
10683        </entry>
10684       </row>
10685       <row>
10686        <entry><para><literal>json_populate_record(base anyelement, from_json json)</literal>
10687          </para><para><literal>jsonb_populate_record(base anyelement, from_json jsonb)</literal>
10688        </para></entry>
10689        <entry><type>anyelement</type></entry>
10690        <entry>
10691          Expands the object in <replaceable>from_json</replaceable> to a row
10692          whose columns match the record type defined by <replaceable>base</>
10693          (see note below).
10694        </entry>
10695        <entry><literal>select * from json_populate_record(null::myrowtype, '{"a":1,"b":2}')</literal></entry>
10696        <entry>
10697 <programlisting>
10698  a | b
10699 ---+---
10700  1 | 2
10701 </programlisting>
10702        </entry>
10703       </row>
10704       <row>
10705        <entry><para><literal>json_populate_recordset(base anyelement, from_json json)</literal>
10706          </para><para><literal>jsonb_populate_recordset(base anyelement, from_json jsonb)</literal>
10707        </para></entry>
10708        <entry><type>setof anyelement</type></entry>
10709        <entry>
10710          Expands the outermost array of objects
10711          in <replaceable>from_json</replaceable> to a set of rows whose
10712          columns match the record type defined by <replaceable>base</> (see
10713          note below).
10714        </entry>
10715        <entry><literal>select * from json_populate_recordset(null::myrowtype, '[{"a":1,"b":2},{"a":3,"b":4}]')</literal></entry>
10716        <entry>
10717 <programlisting>
10718  a | b
10719 ---+---
10720  1 | 2
10721  3 | 4
10722 </programlisting>
10723        </entry>
10724       </row>
10725       <row>
10726        <entry><para><literal>json_array_elements(json)</literal>
10727          </para><para><literal>jsonb_array_elements(jsonb)</literal>
10728        </para></entry>
10729        <entry><para><type>setof json</type>
10730          </para><para><type>setof jsonb</type>
10731        </para></entry>
10732        <entry>
10733          Expands a JSON array to a set of JSON values.
10734        </entry>
10735        <entry><literal>select * from json_array_elements('[1,true, [2,false]]')</literal></entry>
10736        <entry>
10737 <programlisting>
10738    value
10739 -----------
10740  1
10741  true
10742  [2,false]
10743 </programlisting>
10744        </entry>
10745       </row>
10746       <row>
10747        <entry><para><literal>json_array_elements_text(json)</literal>
10748          </para><para><literal>jsonb_array_elements_text(jsonb)</literal>
10749        </para></entry>
10750        <entry><type>setof text</type></entry>
10751        <entry>
10752          Expands a JSON array to a set of <type>text</> values.
10753        </entry>
10754        <entry><literal>select * from json_array_elements_text('["foo", "bar"]')</literal></entry>
10755        <entry>
10756 <programlisting>
10757    value
10758 -----------
10759  foo
10760  bar
10761 </programlisting>
10762        </entry>
10763       </row>
10764       <row>
10765        <entry><para><literal>json_typeof(json)</literal>
10766          </para><para><literal>jsonb_typeof(jsonb)</literal>
10767        </para></entry>
10768        <entry><type>text</type></entry>
10769        <entry>
10770          Returns the type of the outermost JSON value as a text string.
10771          Possible types are
10772          <literal>object</>, <literal>array</>, <literal>string</>, <literal>number</>,
10773          <literal>boolean</>, and <literal>null</>.
10774        </entry>
10775        <entry><literal>json_typeof('-123.4')</literal></entry>
10776        <entry><literal>number</literal></entry>
10777       </row>
10778       <row>
10779        <entry><para><literal>json_to_record(json)</literal>
10780           </para><para><literal>jsonb_to_record(jsonb)</literal>
10781        </para></entry>
10782        <entry><type>record</type></entry>
10783        <entry>
10784          Builds an arbitrary record from a JSON object (see note below).  As
10785          with all functions returning <type>record</>, the caller must
10786          explicitly define the structure of the record with an <literal>AS</>
10787          clause.
10788        </entry>
10789        <entry><literal>select * from json_to_record('{"a":1,"b":[1,2,3],"c":"bar"}') as x(a int, b text, d text) </literal></entry>
10790        <entry>
10791 <programlisting>
10792  a |    b    | d
10793 ---+---------+---
10794  1 | [1,2,3] |
10795 </programlisting>
10796        </entry>
10797       </row>
10798       <row>
10799        <entry><para><literal>json_to_recordset(json)</literal>
10800          </para><para><literal>jsonb_to_recordset(jsonb)</literal>
10801        </para></entry>
10802        <entry><type>setof record</type></entry>
10803        <entry>
10804          Builds an arbitrary set of records from a JSON array of objects (see
10805          note below).  As with all functions returning <type>record</>, the
10806          caller must explicitly define the structure of the record with
10807          an <literal>AS</> clause.
10808        </entry>
10809        <entry><literal>select * from json_to_recordset('[{"a":1,"b":"foo"},{"a":"2","c":"bar"}]') as x(a int, b text);</literal></entry>
10810        <entry>
10811 <programlisting>
10812  a |  b
10813 ---+-----
10814  1 | foo
10815  2 |
10816 </programlisting>
10817        </entry>
10818       </row>
10819       <row>
10820        <entry><para><literal>json_strip_nulls(from_json json)</literal>
10821          </para><para><literal>jsonb_strip_nulls(from_json jsonb)</literal>
10822        </para></entry>
10823        <entry><para><type>json</type></para><para><type>jsonb</type></para></entry>
10824        <entry>
10825          Returns <replaceable>from_json</replaceable>
10826          with all object fields that have null values omitted. Other null values
10827          are untouched.
10828        </entry>
10829        <entry><literal>json_strip_nulls('[{"f1":1,"f2":null},2,null,3]')</literal></entry>
10830        <entry><literal>[{"f1":1},2,null,3]</literal></entry>
10831        </row>
10832       <row>
10833        <entry><para><literal>jsonb_replace(target jsonb, path text[], replacement jsonb)</literal>
10834          </para></entry>
10835        <entry><para><type>jsonb</type></para></entry>
10836        <entry>
10837          Returns <replaceable>target</replaceable>
10838          with the section designated by  <replaceable>path</replaceable>
10839          replaced by <replaceable>replacement</replaceable>.
10840        </entry>
10841        <entry><literal>jsonb_replace('[{"f1":1,"f2":null},2,null,3]', '{0,f1}','[2,3,4]')</literal></entry>
10842        <entry><literal>[{"f1":[2,3,4],"f2":null},2,null,3]</literal>
10843         </entry>
10844        </row>
10845       <row>
10846        <entry><para><literal>jsonb_pretty(from_json jsonb)</literal>
10847          </para></entry>
10848        <entry><para><type>text</type></para></entry>
10849        <entry>
10850          Returns <replaceable>from_json</replaceable>
10851          as indented json text.
10852        </entry>
10853        <entry><literal>jsonb_pretty('[{"f1":1,"f2":null},2,null,3]')</literal></entry>
10854        <entry>
10855 <programlisting>                    
10856  [
10857      {
10858          "f1": 1,
10859          "f2": null
10860      },
10861      2,
10862      null,
10863      3
10864  ]
10865 </programlisting>
10866         </entry>
10867        </row>
10868      </tbody>
10869     </tgroup>
10870    </table>
10871
10872   <note>
10873     <para>
10874       Many of these functions and operators will convert Unicode escapes in
10875       JSON strings to the appropriate single character.  This is a non-issue
10876       if the input is type <type>jsonb</>, because the conversion was already
10877       done; but for <type>json</> input, this may result in throwing an error,
10878       as noted in <xref linkend="datatype-json">.
10879     </para>
10880   </note>
10881
10882   <note>
10883     <para>
10884       In <function>json_populate_record</>, <function>json_populate_recordset</>,
10885       <function>json_to_record</> and <function>json_to_recordset</>,
10886       type coercion from the JSON is <quote>best effort</> and may not result
10887       in desired values for some types.  JSON keys are matched to
10888       identical column names in the target row type.  JSON fields that do not
10889       appear in the target row type will be omitted from the output, and
10890       target columns that do not match any JSON field will simply be NULL.
10891     </para>
10892   </note>
10893
10894   <note>
10895     <para>
10896       The <literal>json_typeof</> function's <literal>null</> return value
10897       should not be confused with a SQL NULL.  While
10898       calling <literal>json_typeof('null'::json)</> will
10899       return <literal>null</>, calling <literal>json_typeof(NULL::json)</>
10900       will return a SQL NULL.
10901     </para>
10902   </note>
10903
10904   <note>
10905     <para>
10906       If the argument to <literal>json_strip_nulls</> contains duplicate
10907       field names in any object, the result could be semantically somewhat
10908       different, depending on the order in which they occur. This is not an
10909       issue for <literal>jsonb_strip_nulls</> since jsonb values never have
10910       duplicate object field names.
10911     </para>
10912   </note>
10913
10914   <para>
10915     See also <xref linkend="functions-aggregate"> for the aggregate
10916     function <function>json_agg</function> which aggregates record
10917     values as JSON, and the aggregate function
10918     <function>json_object_agg</function> which aggregates pairs of values
10919     into a JSON object, and their <type>jsonb</type> equivalents,
10920     <function>jsonb_agg</> and <function>jsonb_object_agg</>.
10921   </para>
10922
10923  </sect1>
10924
10925  <sect1 id="functions-sequence">
10926   <title>Sequence Manipulation Functions</title>
10927
10928   <indexterm>
10929    <primary>sequence</primary>
10930   </indexterm>
10931   <indexterm>
10932    <primary>nextval</primary>
10933   </indexterm>
10934   <indexterm>
10935    <primary>currval</primary>
10936   </indexterm>
10937   <indexterm>
10938    <primary>lastval</primary>
10939   </indexterm>
10940   <indexterm>
10941    <primary>setval</primary>
10942   </indexterm>
10943
10944   <para>
10945    This section describes functions for operating on <firstterm>sequence
10946    objects</firstterm>, also called sequence generators or just sequences.
10947    Sequence objects are special single-row tables created with <xref
10948    linkend="sql-createsequence">.
10949    Sequence objects are commonly used to generate unique identifiers
10950    for rows of a table.  The sequence functions, listed in <xref
10951    linkend="functions-sequence-table">, provide simple, multiuser-safe
10952    methods for obtaining successive sequence values from sequence
10953    objects.
10954   </para>
10955
10956    <table id="functions-sequence-table">
10957     <title>Sequence Functions</title>
10958     <tgroup cols="3">
10959      <thead>
10960       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
10961      </thead>
10962
10963      <tbody>
10964       <row>
10965         <entry><literal><function>currval(<type>regclass</type>)</function></literal></entry>
10966         <entry><type>bigint</type></entry>
10967         <entry>Return value most recently obtained with
10968         <function>nextval</function> for specified sequence</entry>
10969       </row>
10970       <row>
10971         <entry><literal><function>lastval()</function></literal></entry>
10972         <entry><type>bigint</type></entry>
10973         <entry>Return value most recently obtained with
10974         <function>nextval</function> for any sequence</entry>
10975       </row>
10976       <row>
10977         <entry><literal><function>nextval(<type>regclass</type>)</function></literal></entry>
10978         <entry><type>bigint</type></entry>
10979         <entry>Advance sequence and return new value</entry>
10980       </row>
10981       <row>
10982         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>)</function></literal></entry>
10983         <entry><type>bigint</type></entry>
10984         <entry>Set sequence's current value</entry>
10985       </row>
10986       <row>
10987         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</function></literal></entry>
10988         <entry><type>bigint</type></entry>
10989         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
10990       </row>
10991      </tbody>
10992     </tgroup>
10993    </table>
10994
10995   <para>
10996    The sequence to be operated on by a sequence function is specified by
10997    a <type>regclass</> argument, which is simply the OID of the sequence in the
10998    <structname>pg_class</> system catalog.  You do not have to look up the
10999    OID by hand, however, since the <type>regclass</> data type's input
11000    converter will do the work for you.  Just write the sequence name enclosed
11001    in single quotes so that it looks like a literal constant.  For
11002    compatibility with the handling of ordinary
11003    <acronym>SQL</acronym> names, the string will be converted to lower case
11004    unless it contains double quotes around the sequence name.  Thus:
11005 <programlisting>
11006 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
11007 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
11008 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
11009 </programlisting>
11010    The sequence name can be schema-qualified if necessary:
11011 <programlisting>
11012 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
11013 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
11014 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
11015 </programlisting>
11016    See <xref linkend="datatype-oid"> for more information about
11017    <type>regclass</>.
11018   </para>
11019
11020   <note>
11021    <para>
11022     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
11023     sequence functions were of type <type>text</>, not <type>regclass</>, and
11024     the above-described conversion from a text string to an OID value would
11025     happen at run time during each call.  For backward compatibility, this
11026     facility still exists, but internally it is now handled as an implicit
11027     coercion from <type>text</> to <type>regclass</> before the function is
11028     invoked.
11029    </para>
11030
11031    <para>
11032     When you write the argument of a sequence function as an unadorned
11033     literal string, it becomes a constant of type <type>regclass</>.
11034     Since this is really just an OID, it will track the originally
11035     identified sequence despite later renaming, schema reassignment,
11036     etc.  This <quote>early binding</> behavior is usually desirable for
11037     sequence references in column defaults and views.  But sometimes you might
11038     want <quote>late binding</> where the sequence reference is resolved
11039     at run time.  To get late-binding behavior, force the constant to be
11040     stored as a <type>text</> constant instead of <type>regclass</>:
11041 <programlisting>
11042 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
11043 </programlisting>
11044     Note that late binding was the only behavior supported in
11045     <productname>PostgreSQL</productname> releases before 8.1, so you
11046     might need to do this to preserve the semantics of old applications.
11047    </para>
11048
11049    <para>
11050     Of course, the argument of a sequence function can be an expression
11051     as well as a constant.  If it is a text expression then the implicit
11052     coercion will result in a run-time lookup.
11053    </para>
11054   </note>
11055
11056   <para>
11057    The available sequence functions are:
11058
11059     <variablelist>
11060      <varlistentry>
11061       <term><function>nextval</function></term>
11062       <listitem>
11063        <para>
11064         Advance the sequence object to its next value and return that
11065         value.  This is done atomically: even if multiple sessions
11066         execute <function>nextval</function> concurrently, each will safely receive
11067         a distinct sequence value.
11068        </para>
11069
11070        <para>
11071         If a sequence object has been created with default parameters,
11072         successive <function>nextval</function> calls will return successive
11073         values beginning with 1.  Other behaviors can be obtained by using
11074         special parameters in the <xref linkend="sql-createsequence"> command;
11075         see its command reference page for more information.
11076        </para>
11077
11078        <important>
11079         <para>
11080          To avoid blocking concurrent transactions that obtain numbers from the
11081          same sequence, a <function>nextval</function> operation is never
11082          rolled back; that is, once a value has been fetched it is considered
11083          used, even if the transaction that did the
11084          <function>nextval</function> later aborts.  This means that aborted
11085          transactions might leave unused <quote>holes</quote> in the sequence
11086          of assigned values.
11087         </para>
11088        </important>
11089
11090       </listitem>
11091      </varlistentry>
11092
11093      <varlistentry>
11094       <term><function>currval</function></term>
11095       <listitem>
11096        <para>
11097         Return the value most recently obtained by <function>nextval</function>
11098         for this sequence in the current session.  (An error is
11099         reported if <function>nextval</function> has never been called for this
11100         sequence in this session.)  Because this is returning
11101         a session-local value, it gives a predictable answer whether or not
11102         other sessions have executed <function>nextval</function> since the
11103         current session did.
11104        </para>
11105       </listitem>
11106      </varlistentry>
11107
11108      <varlistentry>
11109       <term><function>lastval</function></term>
11110       <listitem>
11111        <para>
11112         Return the value most recently returned by
11113         <function>nextval</> in the current session. This function is
11114         identical to <function>currval</function>, except that instead
11115         of taking the sequence name as an argument it fetches the
11116         value of the last sequence used by <function>nextval</function>
11117         in the current session. It is an error to call
11118         <function>lastval</function> if <function>nextval</function>
11119         has not yet been called in the current session.
11120        </para>
11121       </listitem>
11122      </varlistentry>
11123
11124      <varlistentry>
11125       <term><function>setval</function></term>
11126       <listitem>
11127        <para>
11128         Reset the sequence object's counter value.  The two-parameter
11129         form sets the sequence's <literal>last_value</literal> field to the
11130         specified value and sets its <literal>is_called</literal> field to
11131         <literal>true</literal>, meaning that the next
11132         <function>nextval</function> will advance the sequence before
11133         returning a value.  The value reported by <function>currval</> is
11134         also set to the specified value.  In the three-parameter form,
11135         <literal>is_called</literal> can be set to either <literal>true</literal>
11136         or <literal>false</literal>.  <literal>true</> has the same effect as
11137         the two-parameter form. If it is set to <literal>false</literal>, the
11138         next <function>nextval</function> will return exactly the specified
11139         value, and sequence advancement commences with the following
11140         <function>nextval</function>.  Furthermore, the value reported by
11141         <function>currval</> is not changed in this case.  For example,
11142
11143 <screen>
11144 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
11145 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
11146 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
11147 </screen>
11148
11149         The result returned by <function>setval</function> is just the value of its
11150         second argument.
11151        </para>
11152        <important>
11153         <para>
11154          Because sequences are non-transactional, changes made by
11155          <function>setval</function> are not undone if the transaction rolls
11156          back.
11157         </para>
11158        </important>
11159       </listitem>
11160      </varlistentry>
11161     </variablelist>
11162   </para>
11163
11164  </sect1>
11165
11166
11167  <sect1 id="functions-conditional">
11168   <title>Conditional Expressions</title>
11169
11170   <indexterm>
11171    <primary>CASE</primary>
11172   </indexterm>
11173
11174   <indexterm>
11175    <primary>conditional expression</primary>
11176   </indexterm>
11177
11178   <para>
11179    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
11180    available in <productname>PostgreSQL</productname>.
11181   </para>
11182
11183   <tip>
11184    <para>
11185     If your needs go beyond the capabilities of these conditional
11186     expressions, you might want to consider writing a stored procedure
11187     in a more expressive programming language.
11188    </para>
11189   </tip>
11190
11191   <sect2 id="functions-case">
11192    <title><literal>CASE</></title>
11193
11194   <para>
11195    The <acronym>SQL</acronym> <token>CASE</token> expression is a
11196    generic conditional expression, similar to if/else statements in
11197    other programming languages:
11198
11199 <synopsis>
11200 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
11201      <optional>WHEN ...</optional>
11202      <optional>ELSE <replaceable>result</replaceable></optional>
11203 END
11204 </synopsis>
11205
11206    <token>CASE</token> clauses can be used wherever
11207    an expression is valid.  Each <replaceable>condition</replaceable> is an
11208    expression that returns a <type>boolean</type> result.  If the condition's
11209    result is true, the value of the <token>CASE</token> expression is the
11210    <replaceable>result</replaceable> that follows the condition, and the
11211    remainder of the <token>CASE</token> expression is not processed.  If the
11212    condition's result is not true, any subsequent <token>WHEN</token> clauses
11213    are examined in the same manner.  If no <token>WHEN</token>
11214    <replaceable>condition</replaceable> yields true, the value of the
11215    <token>CASE</> expression is the <replaceable>result</replaceable> of the
11216    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
11217    omitted and no condition is true, the result is null.
11218   </para>
11219
11220    <para>
11221     An example:
11222 <screen>
11223 SELECT * FROM test;
11224
11225  a
11226 ---
11227  1
11228  2
11229  3
11230
11231
11232 SELECT a,
11233        CASE WHEN a=1 THEN 'one'
11234             WHEN a=2 THEN 'two'
11235             ELSE 'other'
11236        END
11237     FROM test;
11238
11239  a | case
11240 ---+-------
11241  1 | one
11242  2 | two
11243  3 | other
11244 </screen>
11245    </para>
11246
11247   <para>
11248    The data types of all the <replaceable>result</replaceable>
11249    expressions must be convertible to a single output type.
11250    See <xref linkend="typeconv-union-case"> for more details.
11251   </para>
11252
11253   <para>
11254    There is a <quote>simple</> form of <token>CASE</token> expression
11255    that is a variant of the general form above:
11256
11257 <synopsis>
11258 CASE <replaceable>expression</replaceable>
11259     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
11260     <optional>WHEN ...</optional>
11261     <optional>ELSE <replaceable>result</replaceable></optional>
11262 END
11263 </synopsis>
11264
11265    The first
11266    <replaceable>expression</replaceable> is computed, then compared to
11267    each of the <replaceable>value</replaceable> expressions in the
11268    <token>WHEN</token> clauses until one is found that is equal to it.  If
11269    no match is found, the <replaceable>result</replaceable> of the
11270    <token>ELSE</token> clause (or a null value) is returned.  This is similar
11271    to the <function>switch</function> statement in C.
11272   </para>
11273
11274    <para>
11275     The example above can be written using the simple
11276     <token>CASE</token> syntax:
11277 <screen>
11278 SELECT a,
11279        CASE a WHEN 1 THEN 'one'
11280               WHEN 2 THEN 'two'
11281               ELSE 'other'
11282        END
11283     FROM test;
11284
11285  a | case
11286 ---+-------
11287  1 | one
11288  2 | two
11289  3 | other
11290 </screen>
11291    </para>
11292
11293    <para>
11294     A <token>CASE</token> expression does not evaluate any subexpressions
11295     that are not needed to determine the result.  For example, this is a
11296     possible way of avoiding a division-by-zero failure:
11297 <programlisting>
11298 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
11299 </programlisting>
11300    </para>
11301
11302    <note>
11303     <para>
11304      As described in <xref linkend="syntax-express-eval">, there are various
11305      situations in which subexpressions of an expression are evaluated at
11306      different times, so that the principle that <quote><token>CASE</token>
11307      evaluates only necessary subexpressions</quote> is not ironclad.  For
11308      example a constant <literal>1/0</> subexpression will usually result in
11309      a division-by-zero failure at planning time, even if it's within
11310      a <token>CASE</token> arm that would never be entered at run time.
11311     </para>
11312    </note>
11313   </sect2>
11314
11315   <sect2 id="functions-coalesce-nvl-ifnull">
11316    <title><literal>COALESCE</></title>
11317
11318   <indexterm>
11319    <primary>COALESCE</primary>
11320   </indexterm>
11321
11322   <indexterm>
11323    <primary>NVL</primary>
11324   </indexterm>
11325
11326   <indexterm>
11327    <primary>IFNULL</primary>
11328   </indexterm>
11329
11330 <synopsis>
11331 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
11332 </synopsis>
11333
11334   <para>
11335    The <function>COALESCE</function> function returns the first of its
11336    arguments that is not null.  Null is returned only if all arguments
11337    are null.  It is often used to substitute a default value for
11338    null values when data is retrieved for display, for example:
11339 <programlisting>
11340 SELECT COALESCE(description, short_description, '(none)') ...
11341 </programlisting>
11342    This returns <varname>description</> if it is not null, otherwise
11343    <varname>short_description</> if it is not null, otherwise <literal>(none)</>.
11344   </para>
11345
11346    <para>
11347     Like a <token>CASE</token> expression, <function>COALESCE</function> only
11348     evaluates the arguments that are needed to determine the result;
11349     that is, arguments to the right of the first non-null argument are
11350     not evaluated.  This SQL-standard function provides capabilities similar
11351     to <function>NVL</> and <function>IFNULL</>, which are used in some other
11352     database systems.
11353    </para>
11354   </sect2>
11355
11356   <sect2 id="functions-nullif">
11357    <title><literal>NULLIF</></title>
11358
11359   <indexterm>
11360    <primary>NULLIF</primary>
11361   </indexterm>
11362
11363 <synopsis>
11364 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
11365 </synopsis>
11366
11367   <para>
11368    The <function>NULLIF</function> function returns a null value if
11369    <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
11370    otherwise it returns <replaceable>value1</replaceable>.
11371    This can be used to perform the inverse operation of the
11372    <function>COALESCE</function> example given above:
11373 <programlisting>
11374 SELECT NULLIF(value, '(none)') ...
11375 </programlisting>
11376   </para>
11377   <para>
11378    In this example, if <literal>value</literal> is <literal>(none)</>,
11379    null is returned, otherwise the value of <literal>value</literal>
11380    is returned.
11381   </para>
11382
11383   </sect2>
11384
11385   <sect2 id="functions-greatest-least">
11386    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
11387
11388   <indexterm>
11389    <primary>GREATEST</primary>
11390   </indexterm>
11391   <indexterm>
11392    <primary>LEAST</primary>
11393   </indexterm>
11394
11395 <synopsis>
11396 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
11397 </synopsis>
11398 <synopsis>
11399 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
11400 </synopsis>
11401
11402    <para>
11403     The <function>GREATEST</> and <function>LEAST</> functions select the
11404     largest or smallest value from a list of any number of expressions.
11405     The expressions must all be convertible to a common data type, which
11406     will be the type of the result
11407     (see <xref linkend="typeconv-union-case"> for details).  NULL values
11408     in the list are ignored.  The result will be NULL only if all the
11409     expressions evaluate to NULL.
11410    </para>
11411
11412    <para>
11413     Note that <function>GREATEST</> and <function>LEAST</> are not in
11414     the SQL standard, but are a common extension.  Some other databases
11415     make them return NULL if any argument is NULL, rather than only when
11416     all are NULL.
11417    </para>
11418   </sect2>
11419  </sect1>
11420
11421  <sect1 id="functions-array">
11422   <title>Array Functions and Operators</title>
11423
11424   <para>
11425    <xref linkend="array-operators-table"> shows the operators
11426    available for array types.
11427   </para>
11428
11429     <table id="array-operators-table">
11430      <title>Array Operators</title>
11431      <tgroup cols="4">
11432       <thead>
11433        <row>
11434         <entry>Operator</entry>
11435         <entry>Description</entry>
11436         <entry>Example</entry>
11437         <entry>Result</entry>
11438        </row>
11439       </thead>
11440       <tbody>
11441        <row>
11442         <entry> <literal>=</literal> </entry>
11443         <entry>equal</entry>
11444         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
11445         <entry><literal>t</literal></entry>
11446        </row>
11447
11448        <row>
11449         <entry> <literal>&lt;&gt;</literal> </entry>
11450         <entry>not equal</entry>
11451         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
11452         <entry><literal>t</literal></entry>
11453        </row>
11454
11455        <row>
11456         <entry> <literal>&lt;</literal> </entry>
11457         <entry>less than</entry>
11458         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
11459         <entry><literal>t</literal></entry>
11460        </row>
11461
11462        <row>
11463         <entry> <literal>&gt;</literal> </entry>
11464         <entry>greater than</entry>
11465         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
11466         <entry><literal>t</literal></entry>
11467        </row>
11468
11469        <row>
11470         <entry> <literal>&lt;=</literal> </entry>
11471         <entry>less than or equal</entry>
11472         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
11473         <entry><literal>t</literal></entry>
11474        </row>
11475
11476        <row>
11477         <entry> <literal>&gt;=</literal> </entry>
11478         <entry>greater than or equal</entry>
11479         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
11480         <entry><literal>t</literal></entry>
11481        </row>
11482
11483        <row>
11484         <entry> <literal>@&gt;</literal> </entry>
11485         <entry>contains</entry>
11486         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
11487         <entry><literal>t</literal></entry>
11488        </row>
11489
11490        <row>
11491         <entry> <literal>&lt;@</literal> </entry>
11492         <entry>is contained by</entry>
11493         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
11494         <entry><literal>t</literal></entry>
11495        </row>
11496
11497        <row>
11498         <entry> <literal>&amp;&amp;</literal> </entry>
11499         <entry>overlap (have elements in common)</entry>
11500         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
11501         <entry><literal>t</literal></entry>
11502        </row>
11503
11504        <row>
11505         <entry> <literal>||</literal> </entry>
11506         <entry>array-to-array concatenation</entry>
11507         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
11508         <entry><literal>{1,2,3,4,5,6}</literal></entry>
11509        </row>
11510
11511        <row>
11512         <entry> <literal>||</literal> </entry>
11513         <entry>array-to-array concatenation</entry>
11514         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
11515         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
11516        </row>
11517
11518        <row>
11519         <entry> <literal>||</literal> </entry>
11520         <entry>element-to-array concatenation</entry>
11521         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
11522         <entry><literal>{3,4,5,6}</literal></entry>
11523        </row>
11524
11525        <row>
11526         <entry> <literal>||</literal> </entry>
11527         <entry>array-to-element concatenation</entry>
11528         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
11529         <entry><literal>{4,5,6,7}</literal></entry>
11530        </row>
11531       </tbody>
11532      </tgroup>
11533     </table>
11534
11535   <para>
11536    Array comparisons compare the array contents element-by-element,
11537    using the default B-tree comparison function for the element data type.
11538    In multidimensional arrays the elements are visited in row-major order
11539    (last subscript varies most rapidly).
11540    If the contents of two arrays are equal but the dimensionality is
11541    different, the first difference in the dimensionality information
11542    determines the sort order.  (This is a change from versions of
11543    <productname>PostgreSQL</> prior to 8.2: older versions would claim
11544    that two arrays with the same contents were equal, even if the
11545    number of dimensions or subscript ranges were different.)
11546   </para>
11547
11548   <para>
11549    See <xref linkend="arrays"> for more details about array operator
11550    behavior.  See <xref linkend="indexes-types"> for more details about
11551    which operators support indexed operations.
11552   </para>
11553
11554   <para>
11555    <xref linkend="array-functions-table"> shows the functions
11556    available for use with array types. See <xref linkend="arrays">
11557    for more information  and examples of the use of these functions.
11558   </para>
11559
11560   <indexterm>
11561     <primary>array_append</primary>
11562   </indexterm>
11563   <indexterm>
11564     <primary>array_cat</primary>
11565   </indexterm>
11566   <indexterm>
11567     <primary>array_ndims</primary>
11568   </indexterm>
11569   <indexterm>
11570     <primary>array_dims</primary>
11571   </indexterm>
11572   <indexterm>
11573     <primary>array_fill</primary>
11574   </indexterm>
11575   <indexterm>
11576     <primary>array_length</primary>
11577   </indexterm>
11578   <indexterm>
11579     <primary>array_lower</primary>
11580   </indexterm>
11581   <indexterm>
11582     <primary>array_position</primary>
11583   </indexterm>
11584   <indexterm>
11585     <primary>array_positions</primary>
11586   </indexterm>
11587   <indexterm>
11588     <primary>array_prepend</primary>
11589   </indexterm>
11590   <indexterm>
11591     <primary>array_remove</primary>
11592   </indexterm>
11593   <indexterm>
11594     <primary>array_replace</primary>
11595   </indexterm>
11596   <indexterm>
11597     <primary>array_to_string</primary>
11598   </indexterm>
11599  <indexterm>
11600     <primary>array_upper</primary>
11601   </indexterm>
11602   <indexterm>
11603     <primary>cardinality</primary>
11604   </indexterm>
11605   <indexterm>
11606     <primary>string_to_array</primary>
11607   </indexterm>
11608   <indexterm>
11609     <primary>unnest</primary>
11610   </indexterm>
11611
11612     <table id="array-functions-table">
11613      <title>Array Functions</title>
11614      <tgroup cols="5">
11615       <thead>
11616        <row>
11617         <entry>Function</entry>
11618         <entry>Return Type</entry>
11619         <entry>Description</entry>
11620         <entry>Example</entry>
11621         <entry>Result</entry>
11622        </row>
11623       </thead>
11624       <tbody>
11625        <row>
11626         <entry>
11627          <literal>
11628           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
11629          </literal>
11630         </entry>
11631         <entry><type>anyarray</type></entry>
11632         <entry>append an element to the end of an array</entry>
11633         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
11634         <entry><literal>{1,2,3}</literal></entry>
11635        </row>
11636        <row>
11637         <entry>
11638          <literal>
11639           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
11640          </literal>
11641         </entry>
11642         <entry><type>anyarray</type></entry>
11643         <entry>concatenate two arrays</entry>
11644         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
11645         <entry><literal>{1,2,3,4,5}</literal></entry>
11646        </row>
11647        <row>
11648         <entry>
11649          <literal>
11650           <function>array_ndims</function>(<type>anyarray</type>)
11651          </literal>
11652         </entry>
11653         <entry><type>int</type></entry>
11654         <entry>returns the number of dimensions of the array</entry>
11655         <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
11656         <entry><literal>2</literal></entry>
11657        </row>
11658        <row>
11659         <entry>
11660          <literal>
11661           <function>array_dims</function>(<type>anyarray</type>)
11662          </literal>
11663         </entry>
11664         <entry><type>text</type></entry>
11665         <entry>returns a text representation of array's dimensions</entry>
11666         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
11667         <entry><literal>[1:2][1:3]</literal></entry>
11668        </row>
11669        <row>
11670         <entry>
11671          <literal>
11672           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
11673           <optional>, <type>int[]</type></optional>)
11674          </literal>
11675         </entry>
11676         <entry><type>anyarray</type></entry>
11677         <entry>returns an array initialized with supplied value and
11678          dimensions, optionally with lower bounds other than 1</entry>
11679         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
11680         <entry><literal>[2:4]={7,7,7}</literal></entry>
11681        </row>
11682        <row>
11683         <entry>
11684          <literal>
11685           <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
11686          </literal>
11687         </entry>
11688         <entry><type>int</type></entry>
11689         <entry>returns the length of the requested array dimension</entry>
11690         <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
11691         <entry><literal>3</literal></entry>
11692        </row>
11693        <row>
11694         <entry>
11695          <literal>
11696           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
11697          </literal>
11698         </entry>
11699         <entry><type>int</type></entry>
11700         <entry>returns lower bound of the requested array dimension</entry>
11701         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
11702         <entry><literal>0</literal></entry>
11703        </row>
11704        <row>
11705         <entry>
11706          <literal>
11707           <function>array_position</function>(<type>anyarray</type>, <type>anyelement</type> <optional>, <type>int</type></optional>)
11708          </literal>
11709         </entry>
11710         <entry><type>int</type></entry>
11711         <entry>returns the subscript of the first occurrence of the second
11712         argument in the array, starting at the element indicated by the third
11713         argument or at the first element (array must be one-dimensional)</entry>
11714         <entry><literal>array_position(ARRAY['sun','mon','tue','wed','thu','fri','sat'], 'mon')</literal></entry>
11715         <entry><literal>2</literal></entry>
11716        </row>
11717        <row>
11718         <entry>
11719          <literal>
11720           <function>array_positions</function>(<type>anyarray</type>, <type>anyelement</type>)
11721          </literal>
11722         </entry>
11723         <entry><type>int[]</type></entry>
11724         <entry>returns an array of subscripts of all occurrences of the second
11725         argument in the array given as first argument (array must be
11726         one-dimensional)</entry>
11727         <entry><literal>array_positions(ARRAY['A','A','B','A'], 'A')</literal></entry>
11728         <entry><literal>{1,2,4}</literal></entry>
11729        </row>
11730        <row>
11731         <entry>
11732          <literal>
11733           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
11734          </literal>
11735         </entry>
11736         <entry><type>anyarray</type></entry>
11737         <entry>append an element to the beginning of an array</entry>
11738         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
11739         <entry><literal>{1,2,3}</literal></entry>
11740        </row>
11741        <row>
11742         <entry>
11743          <literal>
11744           <function>array_remove</function>(<type>anyarray</type>, <type>anyelement</type>)
11745          </literal>
11746         </entry>
11747         <entry><type>anyarray</type></entry>
11748         <entry>remove all elements equal to the given value from the array
11749          (array must be one-dimensional)</entry>
11750         <entry><literal>array_remove(ARRAY[1,2,3,2], 2)</literal></entry>
11751         <entry><literal>{1,3}</literal></entry>
11752        </row>
11753        <row>
11754         <entry>
11755          <literal>
11756           <function>array_replace</function>(<type>anyarray</type>, <type>anyelement</type>, <type>anyelement</type>)
11757          </literal>
11758         </entry>
11759         <entry><type>anyarray</type></entry>
11760         <entry>replace each array element equal to the given value with a new value</entry>
11761         <entry><literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal></entry>
11762         <entry><literal>{1,2,3,4}</literal></entry>
11763        </row>
11764        <row>
11765         <entry>
11766          <literal>
11767           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type> <optional>, <type>text</type></optional>)
11768          </literal>
11769         </entry>
11770         <entry><type>text</type></entry>
11771         <entry>concatenates array elements using supplied delimiter and
11772          optional null string</entry>
11773         <entry><literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal></entry>
11774         <entry><literal>1,2,3,*,5</literal></entry>
11775        </row>
11776        <row>
11777         <entry>
11778          <literal>
11779           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
11780          </literal>
11781         </entry>
11782         <entry><type>int</type></entry>
11783         <entry>returns upper bound of the requested array dimension</entry>
11784         <entry><literal>array_upper(ARRAY[1,8,3,7], 1)</literal></entry>
11785         <entry><literal>4</literal></entry>
11786        </row>
11787        <row>
11788         <entry>
11789          <literal>
11790           <function>cardinality</function>(<type>anyarray</type>)
11791          </literal>
11792         </entry>
11793         <entry><type>int</type></entry>
11794         <entry>returns the total number of elements in the array, or 0 if the array is empty</entry>
11795         <entry><literal>cardinality(ARRAY[[1,2],[3,4]])</literal></entry>
11796         <entry><literal>4</literal></entry>
11797        </row>
11798        <row>
11799         <entry>
11800          <literal>
11801           <function>string_to_array</function>(<type>text</type>, <type>text</type> <optional>, <type>text</type></optional>)
11802          </literal>
11803         </entry>
11804         <entry><type>text[]</type></entry>
11805         <entry>splits string into array elements using supplied delimiter and
11806          optional null string</entry>
11807         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~', 'yy')</literal></entry>
11808         <entry><literal>{xx,NULL,zz}</literal></entry>
11809        </row>
11810        <row>
11811         <entry>
11812          <literal>
11813           <function>unnest</function>(<type>anyarray</type>)
11814          </literal>
11815         </entry>
11816         <entry><type>setof anyelement</type></entry>
11817         <entry>expand an array to a set of rows</entry>
11818         <entry><literal>unnest(ARRAY[1,2])</literal></entry>
11819         <entry><literallayout class="monospaced">1
11820 2</literallayout>(2 rows)</entry>
11821        </row>
11822        <row>
11823         <entry>
11824          <literal>
11825           <function>unnest</function>(<type>anyarray</type>, <type>anyarray</type> [, ...])
11826          </literal>
11827         </entry>
11828         <entry><type>setof anyelement, anyelement [, ...]</type></entry>
11829         <entry>expand multiple arrays (possibly of different types) to a set
11830          of rows.  This is only allowed in the FROM clause; see
11831          <xref linkend="queries-tablefunctions"></entry>
11832         <entry><literal>unnest(ARRAY[1,2],ARRAY['foo','bar','baz'])</literal></entry>
11833         <entry><literallayout class="monospaced">1    foo
11834 2    bar
11835 NULL baz</literallayout>(3 rows)</entry>
11836        </row>
11837       </tbody>
11838      </tgroup>
11839     </table>
11840
11841    <para>
11842     In <function>array_position</function> and <function>array_positions</>,
11843     each array element is compared to the searched value using
11844     <literal>IS NOT DISTINCT FROM</literal> semantics.
11845    </para>
11846
11847    <para>
11848     In <function>array_position</function>, <literal>NULL</literal> is returned
11849     if the value is not found.
11850    </para>
11851
11852    <para>
11853     In <function>array_positions</function>, <literal>NULL</literal> is returned
11854     only if the array is <literal>NULL</literal>; if the value is not found in
11855     the array, an empty array is returned instead.
11856    </para>
11857
11858    <para>
11859     In <function>string_to_array</function>, if the delimiter parameter is
11860     NULL, each character in the input string will become a separate element in
11861     the resulting array.  If the delimiter is an empty string, then the entire
11862     input string is returned as a one-element array.  Otherwise the input
11863     string is split at each occurrence of the delimiter string.
11864    </para>
11865
11866    <para>
11867     In <function>string_to_array</function>, if the null-string parameter
11868     is omitted or NULL, none of the substrings of the input will be replaced
11869     by NULL.
11870     In <function>array_to_string</function>, if the null-string parameter
11871     is omitted or NULL, any null elements in the array are simply skipped
11872     and not represented in the output string.
11873    </para>
11874
11875    <note>
11876     <para>
11877      There are two differences in the behavior of <function>string_to_array</>
11878      from pre-9.1 versions of <productname>PostgreSQL</>.
11879      First, it will return an empty (zero-element) array rather than NULL when
11880      the input string is of zero length.  Second, if the delimiter string is
11881      NULL, the function splits the input into individual characters, rather
11882      than returning NULL as before.
11883     </para>
11884    </note>
11885
11886    <para>
11887     See also <xref linkend="functions-aggregate"> about the aggregate
11888     function <function>array_agg</function> for use with arrays.
11889    </para>
11890   </sect1>
11891
11892  <sect1 id="functions-range">
11893   <title>Range Functions and Operators</title>
11894
11895   <para>
11896    See <xref linkend="rangetypes"> for an overview of range types.
11897   </para>
11898
11899   <para>
11900    <xref linkend="range-operators-table"> shows the operators
11901    available for range types.
11902   </para>
11903
11904     <table id="range-operators-table">
11905      <title>Range Operators</title>
11906      <tgroup cols="4">
11907       <thead>
11908        <row>
11909         <entry>Operator</entry>
11910         <entry>Description</entry>
11911         <entry>Example</entry>
11912         <entry>Result</entry>
11913        </row>
11914       </thead>
11915       <tbody>
11916        <row>
11917         <entry> <literal>=</literal> </entry>
11918         <entry>equal</entry>
11919         <entry><literal>int4range(1,5) = '[1,4]'::int4range</literal></entry>
11920         <entry><literal>t</literal></entry>
11921        </row>
11922
11923        <row>
11924         <entry> <literal>&lt;&gt;</literal> </entry>
11925         <entry>not equal</entry>
11926         <entry><literal>numrange(1.1,2.2) &lt;&gt; numrange(1.1,2.3)</literal></entry>
11927         <entry><literal>t</literal></entry>
11928        </row>
11929
11930        <row>
11931         <entry> <literal>&lt;</literal> </entry>
11932         <entry>less than</entry>
11933         <entry><literal>int4range(1,10) &lt; int4range(2,3)</literal></entry>
11934         <entry><literal>t</literal></entry>
11935        </row>
11936
11937        <row>
11938         <entry> <literal>&gt;</literal> </entry>
11939         <entry>greater than</entry>
11940         <entry><literal>int4range(1,10) &gt; int4range(1,5)</literal></entry>
11941         <entry><literal>t</literal></entry>
11942        </row>
11943
11944        <row>
11945         <entry> <literal>&lt;=</literal> </entry>
11946         <entry>less than or equal</entry>
11947         <entry><literal>numrange(1.1,2.2) &lt;= numrange(1.1,2.2)</literal></entry>
11948         <entry><literal>t</literal></entry>
11949        </row>
11950
11951        <row>
11952         <entry> <literal>&gt;=</literal> </entry>
11953         <entry>greater than or equal</entry>
11954         <entry><literal>numrange(1.1,2.2) &gt;= numrange(1.1,2.0)</literal></entry>
11955         <entry><literal>t</literal></entry>
11956        </row>
11957
11958        <row>
11959         <entry> <literal>@&gt;</literal> </entry>
11960         <entry>contains range</entry>
11961         <entry><literal>int4range(2,4) @&gt; int4range(2,3)</literal></entry>
11962         <entry><literal>t</literal></entry>
11963        </row>
11964
11965        <row>
11966         <entry> <literal>@&gt;</literal> </entry>
11967         <entry>contains element</entry>
11968         <entry><literal>'[2011-01-01,2011-03-01)'::tsrange @&gt; '2011-01-10'::timestamp</literal></entry>
11969         <entry><literal>t</literal></entry>
11970        </row>
11971
11972        <row>
11973         <entry> <literal>&lt;@</literal> </entry>
11974         <entry>range is contained by</entry>
11975         <entry><literal>int4range(2,4) &lt;@ int4range(1,7)</literal></entry>
11976         <entry><literal>t</literal></entry>
11977        </row>
11978
11979        <row>
11980         <entry> <literal>&lt;@</literal> </entry>
11981         <entry>element is contained by</entry>
11982         <entry><literal>42 &lt;@ int4range(1,7)</literal></entry>
11983         <entry><literal>f</literal></entry>
11984        </row>
11985
11986        <row>
11987         <entry> <literal>&amp;&amp;</literal> </entry>
11988         <entry>overlap (have points in common)</entry>
11989         <entry><literal>int8range(3,7) &amp;&amp; int8range(4,12)</literal></entry>
11990         <entry><literal>t</literal></entry>
11991        </row>
11992
11993        <row>
11994         <entry> <literal>&lt;&lt;</literal> </entry>
11995         <entry>strictly left of</entry>
11996         <entry><literal>int8range(1,10) &lt;&lt; int8range(100,110)</literal></entry>
11997         <entry><literal>t</literal></entry>
11998        </row>
11999
12000        <row>
12001         <entry> <literal>&gt;&gt;</literal> </entry>
12002         <entry>strictly right of</entry>
12003         <entry><literal>int8range(50,60) &gt;&gt; int8range(20,30)</literal></entry>
12004         <entry><literal>t</literal></entry>
12005        </row>
12006
12007        <row>
12008         <entry> <literal>&amp;&lt;</literal> </entry>
12009         <entry>does not extend to the right of</entry>
12010         <entry><literal>int8range(1,20) &amp;&lt; int8range(18,20)</literal></entry>
12011         <entry><literal>t</literal></entry>
12012        </row>
12013
12014        <row>
12015         <entry> <literal>&amp;&gt;</literal> </entry>
12016         <entry>does not extend to the left of</entry>
12017         <entry><literal>int8range(7,20) &amp;&gt; int8range(5,10)</literal></entry>
12018         <entry><literal>t</literal></entry>
12019        </row>
12020
12021        <row>
12022         <entry> <literal>-|-</literal> </entry>
12023         <entry>is adjacent to</entry>
12024         <entry><literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal></entry>
12025         <entry><literal>t</literal></entry>
12026        </row>
12027
12028        <row>
12029         <entry> <literal>+</literal> </entry>
12030         <entry>union</entry>
12031         <entry><literal>numrange(5,15) + numrange(10,20)</literal></entry>
12032         <entry><literal>[5,20)</literal></entry>
12033        </row>
12034
12035        <row>
12036         <entry> <literal>*</literal> </entry>
12037         <entry>intersection</entry>
12038         <entry><literal>int8range(5,15) * int8range(10,20)</literal></entry>
12039         <entry><literal>[10,15)</literal></entry>
12040        </row>
12041
12042        <row>
12043         <entry> <literal>-</literal> </entry>
12044         <entry>difference</entry>
12045         <entry><literal>int8range(5,15) - int8range(10,20)</literal></entry>
12046         <entry><literal>[5,10)</literal></entry>
12047        </row>
12048
12049       </tbody>
12050      </tgroup>
12051     </table>
12052
12053   <para>
12054    The simple comparison operators <literal>&lt;</literal>,
12055    <literal>&gt;</literal>, <literal>&lt;=</literal>, and
12056    <literal>&gt;=</literal> compare the lower bounds first, and only if those
12057    are equal, compare the upper bounds.  These comparisons are not usually
12058    very useful for ranges, but are provided to allow B-tree indexes to be
12059    constructed on ranges.
12060   </para>
12061
12062   <para>
12063    The left-of/right-of/adjacent operators always return false when an empty
12064    range is involved; that is, an empty range is not considered to be either
12065    before or after any other range.
12066   </para>
12067
12068   <para>
12069    The union and difference operators will fail if the resulting range would
12070    need to contain two disjoint sub-ranges, as such a range cannot be
12071    represented.
12072   </para>
12073
12074   <para>
12075    <xref linkend="range-functions-table"> shows the functions
12076    available for use with range types.
12077   </para>
12078
12079   <indexterm>
12080     <primary>lower</primary>
12081   </indexterm>
12082   <indexterm>
12083     <primary>upper</primary>
12084   </indexterm>
12085   <indexterm>
12086     <primary>isempty</primary>
12087   </indexterm>
12088   <indexterm>
12089     <primary>lower_inc</primary>
12090   </indexterm>
12091   <indexterm>
12092     <primary>upper_inc</primary>
12093   </indexterm>
12094   <indexterm>
12095     <primary>lower_inf</primary>
12096   </indexterm>
12097   <indexterm>
12098     <primary>upper_inf</primary>
12099   </indexterm>
12100
12101     <table id="range-functions-table">
12102      <title>Range Functions</title>
12103      <tgroup cols="5">
12104       <thead>
12105        <row>
12106         <entry>Function</entry>
12107         <entry>Return Type</entry>
12108         <entry>Description</entry>
12109         <entry>Example</entry>
12110         <entry>Result</entry>
12111        </row>
12112       </thead>
12113       <tbody>
12114        <row>
12115         <entry>
12116          <literal>
12117           <function>lower</function>(<type>anyrange</type>)
12118          </literal>
12119         </entry>
12120         <entry>range's element type</entry>
12121         <entry>lower bound of range</entry>
12122         <entry><literal>lower(numrange(1.1,2.2))</literal></entry>
12123         <entry><literal>1.1</literal></entry>
12124        </row>
12125        <row>
12126         <entry>
12127          <literal>
12128           <function>upper</function>(<type>anyrange</type>)
12129          </literal>
12130         </entry>
12131         <entry>range's element type</entry>
12132         <entry>upper bound of range</entry>
12133         <entry><literal>upper(numrange(1.1,2.2))</literal></entry>
12134         <entry><literal>2.2</literal></entry>
12135        </row>
12136        <row>
12137         <entry>
12138          <literal>
12139           <function>isempty</function>(<type>anyrange</type>)
12140          </literal>
12141         </entry>
12142         <entry><type>boolean</type></entry>
12143         <entry>is the range empty?</entry>
12144         <entry><literal>isempty(numrange(1.1,2.2))</literal></entry>
12145         <entry><literal>false</literal></entry>
12146        </row>
12147        <row>
12148         <entry>
12149          <literal>
12150           <function>lower_inc</function>(<type>anyrange</type>)
12151          </literal>
12152         </entry>
12153         <entry><type>boolean</type></entry>
12154         <entry>is the lower bound inclusive?</entry>
12155         <entry><literal>lower_inc(numrange(1.1,2.2))</literal></entry>
12156         <entry><literal>true</literal></entry>
12157        </row>
12158        <row>
12159         <entry>
12160          <literal>
12161           <function>upper_inc</function>(<type>anyrange</type>)
12162          </literal>
12163         </entry>
12164         <entry><type>boolean</type></entry>
12165         <entry>is the upper bound inclusive?</entry>
12166         <entry><literal>upper_inc(numrange(1.1,2.2))</literal></entry>
12167         <entry><literal>false</literal></entry>
12168        </row>
12169        <row>
12170         <entry>
12171          <literal>
12172           <function>lower_inf</function>(<type>anyrange</type>)
12173          </literal>
12174         </entry>
12175         <entry><type>boolean</type></entry>
12176         <entry>is the lower bound infinite?</entry>
12177         <entry><literal>lower_inf('(,)'::daterange)</literal></entry>
12178         <entry><literal>true</literal></entry>
12179        </row>
12180        <row>
12181         <entry>
12182          <literal>
12183           <function>upper_inf</function>(<type>anyrange</type>)
12184          </literal>
12185         </entry>
12186         <entry><type>boolean</type></entry>
12187         <entry>is the upper bound infinite?</entry>
12188         <entry><literal>upper_inf('(,)'::daterange)</literal></entry>
12189         <entry><literal>true</literal></entry>
12190        </row>
12191        <row>
12192         <entry>
12193          <literal>
12194           <function>range_merge</function>(<type>anyrange</type>, <type>anyrange</type>)
12195          </literal>
12196         </entry>
12197         <entry><type>anyrange</type></entry>
12198         <entry>the smallest range which includes both of the given ranges</entry>
12199         <entry><literal>range_merge('[1,2)'::int4range, '[3,4)'::int4range)</literal></entry>
12200         <entry><literal>[1,4)</literal></entry>
12201        </row>
12202       </tbody>
12203      </tgroup>
12204     </table>
12205
12206   <para>
12207    The <function>lower</> and  <function>upper</> functions return null
12208    if the range is empty or the requested bound is infinite.
12209    The <function>lower_inc</function>, <function>upper_inc</function>,
12210    <function>lower_inf</function>, and <function>upper_inf</function>
12211    functions all return false for an empty range.
12212   </para>
12213   </sect1>
12214
12215  <sect1 id="functions-aggregate">
12216   <title>Aggregate Functions</title>
12217
12218   <indexterm zone="functions-aggregate">
12219    <primary>aggregate function</primary>
12220    <secondary>built-in</secondary>
12221   </indexterm>
12222
12223   <para>
12224    <firstterm>Aggregate functions</firstterm> compute a single result
12225    from a set of input values.  The built-in normal aggregate functions
12226    are listed in
12227    <xref linkend="functions-aggregate-table"> and
12228    <xref linkend="functions-aggregate-statistics-table">.
12229    The built-in ordered-set aggregate functions
12230    are listed in <xref linkend="functions-orderedset-table"> and
12231    <xref linkend="functions-hypothetical-table">.
12232    The special syntax considerations for aggregate
12233    functions are explained in <xref linkend="syntax-aggregates">.
12234    Consult <xref linkend="tutorial-agg"> for additional introductory
12235    information.
12236   </para>
12237
12238   <table id="functions-aggregate-table">
12239    <title>General-Purpose Aggregate Functions</title>
12240
12241    <tgroup cols="4">
12242     <thead>
12243      <row>
12244       <entry>Function</entry>
12245       <entry>Argument Type(s)</entry>
12246       <entry>Return Type</entry>
12247       <entry>Description</entry>
12248      </row>
12249     </thead>
12250
12251     <tbody>
12252      <row>
12253       <entry>
12254        <indexterm>
12255         <primary>array_agg</primary>
12256        </indexterm>
12257        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
12258       </entry>
12259       <entry>
12260        any non-array type
12261       </entry>
12262       <entry>
12263        array of the argument type
12264       </entry>
12265       <entry>input values, including nulls, concatenated into an array</entry>
12266      </row>
12267
12268      <row>
12269       <entry>
12270        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
12271       </entry>
12272       <entry>
12273        any array type
12274       </entry>
12275       <entry>
12276        same as argument data type
12277       </entry>
12278       <entry>input arrays concatenated into array of one higher dimension
12279        (inputs must all have same dimensionality,
12280         and cannot be empty or NULL)</entry>
12281      </row>
12282
12283      <row>
12284       <entry>
12285        <indexterm>
12286         <primary>average</primary>
12287        </indexterm>
12288        <indexterm>
12289         <primary>avg</primary>
12290        </indexterm>
12291        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
12292       </entry>
12293       <entry>
12294        <type>smallint</type>, <type>int</type>,
12295        <type>bigint</type>, <type>real</type>, <type>double
12296        precision</type>, <type>numeric</type>, or <type>interval</type>
12297       </entry>
12298       <entry>
12299        <type>numeric</type> for any integer-type argument,
12300        <type>double precision</type> for a floating-point argument,
12301        otherwise the same as the argument data type
12302       </entry>
12303       <entry>the average (arithmetic mean) of all input values</entry>
12304      </row>
12305
12306      <row>
12307       <entry>
12308        <indexterm>
12309         <primary>bit_and</primary>
12310        </indexterm>
12311        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
12312       </entry>
12313       <entry>
12314        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
12315        <type>bit</type>
12316       </entry>
12317       <entry>
12318         same as argument data type
12319       </entry>
12320       <entry>the bitwise AND of all non-null input values, or null if none</entry>
12321      </row>
12322
12323      <row>
12324       <entry>
12325        <indexterm>
12326         <primary>bit_or</primary>
12327        </indexterm>
12328        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
12329       </entry>
12330       <entry>
12331        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
12332        <type>bit</type>
12333       </entry>
12334       <entry>
12335         same as argument data type
12336       </entry>
12337       <entry>the bitwise OR of all non-null input values, or null if none</entry>
12338      </row>
12339
12340      <row>
12341       <entry>
12342        <indexterm>
12343         <primary>bool_and</primary>
12344        </indexterm>
12345        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
12346       </entry>
12347       <entry>
12348        <type>bool</type>
12349       </entry>
12350       <entry>
12351        <type>bool</type>
12352       </entry>
12353       <entry>true if all input values are true, otherwise false</entry>
12354      </row>
12355
12356      <row>
12357       <entry>
12358        <indexterm>
12359         <primary>bool_or</primary>
12360        </indexterm>
12361        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
12362       </entry>
12363       <entry>
12364        <type>bool</type>
12365       </entry>
12366       <entry>
12367        <type>bool</type>
12368       </entry>
12369       <entry>true if at least one input value is true, otherwise false</entry>
12370      </row>
12371
12372      <row>
12373       <entry>
12374        <indexterm>
12375         <primary>count</primary>
12376        </indexterm>
12377        <function>count(*)</function>
12378       </entry>
12379       <entry></entry>
12380       <entry><type>bigint</type></entry>
12381       <entry>number of input rows</entry>
12382      </row>
12383
12384      <row>
12385       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
12386       <entry>any</entry>
12387       <entry><type>bigint</type></entry>
12388       <entry>
12389        number of input rows for which the value of <replaceable
12390        class="parameter">expression</replaceable> is not null
12391       </entry>
12392      </row>
12393
12394      <row>
12395       <entry>
12396        <indexterm>
12397         <primary>every</primary>
12398        </indexterm>
12399        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
12400       </entry>
12401       <entry>
12402        <type>bool</type>
12403       </entry>
12404       <entry>
12405        <type>bool</type>
12406       </entry>
12407       <entry>equivalent to <function>bool_and</function></entry>
12408      </row>
12409
12410      <row>
12411       <entry>
12412        <indexterm>
12413         <primary>json_agg</primary>
12414        </indexterm>
12415        <function>json_agg(<replaceable class="parameter">expression</replaceable>)</function>
12416       </entry>
12417       <entry>
12418        <type>any</type>
12419       </entry>
12420       <entry>
12421        <type>json</type>
12422       </entry>
12423       <entry>aggregates values as a JSON array</entry>
12424      </row>
12425
12426      <row>
12427       <entry>
12428        <indexterm>
12429         <primary>jsonb_agg</primary>
12430        </indexterm>
12431        <function>jsonb_agg(<replaceable class="parameter">expression</replaceable>)</function>
12432       </entry>
12433       <entry>
12434        <type>any</type>
12435       </entry>
12436       <entry>
12437        <type>jsonb</type>
12438       </entry>
12439       <entry>aggregates values as a JSON array</entry>
12440      </row>
12441
12442      <row>
12443       <entry>
12444        <indexterm>
12445         <primary>json_object_agg</primary>
12446        </indexterm>
12447        <function>json_object_agg(<replaceable class="parameter">name</replaceable>, <replaceable class="parameter">value</replaceable>)</function>
12448       </entry>
12449       <entry>
12450        <type>(any, any)</type>
12451       </entry>
12452       <entry>
12453        <type>json</type>
12454       </entry>
12455       <entry>aggregates name/value pairs as a JSON object</entry>
12456      </row>
12457
12458      <row>
12459       <entry>
12460        <indexterm>
12461         <primary>jsonb_object_agg</primary>
12462        </indexterm>
12463        <function>jsonb_object_agg(<replaceable class="parameter">name</replaceable>, <replaceable class="parameter">value</replaceable>)</function>
12464       </entry>
12465       <entry>
12466        <type>(any, any)</type>
12467       </entry>
12468       <entry>
12469        <type>jsonb</type>
12470       </entry>
12471       <entry>aggregates name/value pairs as a JSON object</entry>
12472      </row>
12473
12474      <row>
12475       <entry>
12476        <indexterm>
12477         <primary>max</primary>
12478        </indexterm>
12479        <function>max(<replaceable class="parameter">expression</replaceable>)</function>
12480       </entry>
12481       <entry>any numeric, string, date/time, network, or enum type,
12482              or arrays of these types</entry>
12483       <entry>same as argument type</entry>
12484       <entry>
12485        maximum value of <replaceable
12486        class="parameter">expression</replaceable> across all input
12487        values
12488       </entry>
12489      </row>
12490
12491      <row>
12492       <entry>
12493        <indexterm>
12494         <primary>min</primary>
12495        </indexterm>
12496        <function>min(<replaceable class="parameter">expression</replaceable>)</function>
12497       </entry>
12498       <entry>any numeric, string, date/time, network, or enum type,
12499              or arrays of these types</entry>
12500       <entry>same as argument type</entry>
12501       <entry>
12502        minimum value of <replaceable
12503        class="parameter">expression</replaceable> across all input
12504        values
12505       </entry>
12506      </row>
12507
12508      <row>
12509       <entry>
12510        <indexterm>
12511         <primary>string_agg</primary>
12512        </indexterm>
12513        <function>
12514          string_agg(<replaceable class="parameter">expression</replaceable>,
12515                     <replaceable class="parameter">delimiter</replaceable>)
12516        </function>
12517       </entry>
12518       <entry>
12519        (<type>text</type>, <type>text</type>) or (<type>bytea</type>, <type>bytea</type>)
12520       </entry>
12521       <entry>
12522        same as argument types
12523       </entry>
12524       <entry>input values concatenated into a string, separated by delimiter</entry>
12525      </row>
12526
12527      <row>
12528       <entry>
12529        <indexterm>
12530         <primary>sum</primary>
12531        </indexterm>
12532        <function>sum(<replaceable class="parameter">expression</replaceable>)</function>
12533       </entry>
12534       <entry>
12535        <type>smallint</type>, <type>int</type>,
12536        <type>bigint</type>, <type>real</type>, <type>double
12537        precision</type>, <type>numeric</type>,
12538        <type>interval</type>, or <type>money</>
12539       </entry>
12540       <entry>
12541        <type>bigint</type> for <type>smallint</type> or
12542        <type>int</type> arguments, <type>numeric</type> for
12543        <type>bigint</type> arguments, otherwise the same as the
12544        argument data type
12545       </entry>
12546       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
12547      </row>
12548
12549      <row>
12550       <entry>
12551        <indexterm>
12552         <primary>xmlagg</primary>
12553        </indexterm>
12554        <function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
12555       </entry>
12556       <entry>
12557        <type>xml</type>
12558       </entry>
12559       <entry>
12560        <type>xml</type>
12561       </entry>
12562       <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
12563      </row>
12564     </tbody>
12565    </tgroup>
12566   </table>
12567
12568   <para>
12569    It should be noted that except for <function>count</function>,
12570    these functions return a null value when no rows are selected.  In
12571    particular, <function>sum</function> of no rows returns null, not
12572    zero as one might expect, and <function>array_agg</function>
12573    returns null rather than an empty array when there are no input
12574    rows.  The <function>coalesce</function> function can be used to
12575    substitute zero or an empty array for null when necessary.
12576   </para>
12577
12578   <note>
12579     <indexterm>
12580       <primary>ANY</primary>
12581     </indexterm>
12582     <indexterm>
12583       <primary>SOME</primary>
12584     </indexterm>
12585     <para>
12586       Boolean aggregates <function>bool_and</function> and
12587       <function>bool_or</function> correspond to standard SQL aggregates
12588       <function>every</function> and <function>any</function> or
12589       <function>some</function>.
12590       As for <function>any</function> and <function>some</function>,
12591       it seems that there is an ambiguity built into the standard syntax:
12592 <programlisting>
12593 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
12594 </programlisting>
12595       Here <function>ANY</function> can be considered either as introducing
12596       a subquery, or as being an aggregate function, if the subquery
12597       returns one row with a Boolean value.
12598       Thus the standard name cannot be given to these aggregates.
12599     </para>
12600   </note>
12601
12602   <note>
12603    <para>
12604     Users accustomed to working with other SQL database management
12605     systems might be disappointed by the performance of the
12606     <function>count</function> aggregate when it is applied to the
12607     entire table. A query like:
12608 <programlisting>
12609 SELECT count(*) FROM sometable;
12610 </programlisting>
12611     will require effort proportional to the size of the table:
12612     <productname>PostgreSQL</productname> will need to scan either the
12613     entire table or the entirety of an index which includes all rows in
12614     the table.
12615    </para>
12616   </note>
12617
12618   <para>
12619    The aggregate functions <function>array_agg</function>,
12620    <function>json_agg</function>, <function>jsonb_agg</function>,
12621    <function>json_object_agg</function>, <function>jsonb_object_agg</function>,
12622    <function>string_agg</function>,
12623    and <function>xmlagg</function>, as well as similar user-defined
12624    aggregate functions, produce meaningfully different result values
12625    depending on the order of the input values.  This ordering is
12626    unspecified by default, but can be controlled by writing an
12627    <literal>ORDER BY</> clause within the aggregate call, as shown in
12628    <xref linkend="syntax-aggregates">.
12629    Alternatively, supplying the input values from a sorted subquery
12630    will usually work.  For example:
12631
12632 <screen><![CDATA[
12633 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
12634 ]]></screen>
12635
12636    But this syntax is not allowed in the SQL standard, and is
12637    not portable to other database systems.
12638   </para>
12639
12640   <para>
12641    <xref linkend="functions-aggregate-statistics-table"> shows
12642    aggregate functions typically used in statistical analysis.
12643    (These are separated out merely to avoid cluttering the listing
12644    of more-commonly-used aggregates.)  Where the description mentions
12645    <replaceable class="parameter">N</replaceable>, it means the
12646    number of input rows for which all the input expressions are non-null.
12647    In all cases, null is returned if the computation is meaningless,
12648    for example when <replaceable class="parameter">N</replaceable> is zero.
12649   </para>
12650
12651   <indexterm>
12652    <primary>statistics</primary>
12653   </indexterm>
12654   <indexterm>
12655    <primary>linear regression</primary>
12656   </indexterm>
12657
12658   <table id="functions-aggregate-statistics-table">
12659    <title>Aggregate Functions for Statistics</title>
12660
12661    <tgroup cols="4">
12662     <thead>
12663      <row>
12664       <entry>Function</entry>
12665       <entry>Argument Type</entry>
12666       <entry>Return Type</entry>
12667       <entry>Description</entry>
12668      </row>
12669     </thead>
12670
12671     <tbody>
12672
12673      <row>
12674       <entry>
12675        <indexterm>
12676         <primary>correlation</primary>
12677        </indexterm>
12678        <indexterm>
12679         <primary>corr</primary>
12680        </indexterm>
12681        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12682       </entry>
12683       <entry>
12684        <type>double precision</type>
12685       </entry>
12686       <entry>
12687        <type>double precision</type>
12688       </entry>
12689       <entry>correlation coefficient</entry>
12690      </row>
12691
12692      <row>
12693       <entry>
12694        <indexterm>
12695         <primary>covariance</primary>
12696         <secondary>population</secondary>
12697        </indexterm>
12698        <indexterm>
12699         <primary>covar_pop</primary>
12700        </indexterm>
12701        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12702       </entry>
12703       <entry>
12704        <type>double precision</type>
12705       </entry>
12706       <entry>
12707        <type>double precision</type>
12708       </entry>
12709       <entry>population covariance</entry>
12710      </row>
12711
12712      <row>
12713       <entry>
12714        <indexterm>
12715         <primary>covariance</primary>
12716         <secondary>sample</secondary>
12717        </indexterm>
12718        <indexterm>
12719         <primary>covar_samp</primary>
12720        </indexterm>
12721        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12722       </entry>
12723       <entry>
12724        <type>double precision</type>
12725       </entry>
12726       <entry>
12727        <type>double precision</type>
12728       </entry>
12729       <entry>sample covariance</entry>
12730      </row>
12731
12732      <row>
12733       <entry>
12734        <indexterm>
12735         <primary>regr_avgx</primary>
12736        </indexterm>
12737        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12738       </entry>
12739       <entry>
12740        <type>double precision</type>
12741       </entry>
12742       <entry>
12743        <type>double precision</type>
12744       </entry>
12745       <entry>average of the independent variable
12746       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
12747      </row>
12748
12749      <row>
12750       <entry>
12751        <indexterm>
12752         <primary>regr_avgy</primary>
12753        </indexterm>
12754        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12755       </entry>
12756       <entry>
12757        <type>double precision</type>
12758       </entry>
12759       <entry>
12760        <type>double precision</type>
12761       </entry>
12762       <entry>average of the dependent variable
12763       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
12764      </row>
12765
12766      <row>
12767       <entry>
12768        <indexterm>
12769         <primary>regr_count</primary>
12770        </indexterm>
12771        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12772       </entry>
12773       <entry>
12774        <type>double precision</type>
12775       </entry>
12776       <entry>
12777        <type>bigint</type>
12778       </entry>
12779       <entry>number of input rows in which both expressions are nonnull</entry>
12780      </row>
12781
12782      <row>
12783       <entry>
12784        <indexterm>
12785         <primary>regression intercept</primary>
12786        </indexterm>
12787        <indexterm>
12788         <primary>regr_intercept</primary>
12789        </indexterm>
12790        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12791       </entry>
12792       <entry>
12793        <type>double precision</type>
12794       </entry>
12795       <entry>
12796        <type>double precision</type>
12797       </entry>
12798       <entry>y-intercept of the least-squares-fit linear equation
12799       determined by the (<replaceable
12800       class="parameter">X</replaceable>, <replaceable
12801       class="parameter">Y</replaceable>) pairs</entry>
12802      </row>
12803
12804      <row>
12805       <entry>
12806        <indexterm>
12807         <primary>regr_r2</primary>
12808        </indexterm>
12809        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12810       </entry>
12811       <entry>
12812        <type>double precision</type>
12813       </entry>
12814       <entry>
12815        <type>double precision</type>
12816       </entry>
12817       <entry>square of the correlation coefficient</entry>
12818      </row>
12819
12820      <row>
12821       <entry>
12822        <indexterm>
12823         <primary>regression slope</primary>
12824        </indexterm>
12825        <indexterm>
12826         <primary>regr_slope</primary>
12827        </indexterm>
12828        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12829       </entry>
12830       <entry>
12831        <type>double precision</type>
12832       </entry>
12833       <entry>
12834        <type>double precision</type>
12835       </entry>
12836       <entry>slope of the least-squares-fit linear equation determined
12837       by the (<replaceable class="parameter">X</replaceable>,
12838       <replaceable class="parameter">Y</replaceable>) pairs</entry>
12839      </row>
12840
12841      <row>
12842       <entry>
12843        <indexterm>
12844         <primary>regr_sxx</primary>
12845        </indexterm>
12846        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12847       </entry>
12848       <entry>
12849        <type>double precision</type>
12850       </entry>
12851       <entry>
12852        <type>double precision</type>
12853       </entry>
12854       <entry><literal>sum(<replaceable
12855       class="parameter">X</replaceable>^2) - sum(<replaceable
12856       class="parameter">X</replaceable>)^2/<replaceable
12857       class="parameter">N</replaceable></literal> (<quote>sum of
12858       squares</quote> of the independent variable)</entry>
12859      </row>
12860
12861      <row>
12862       <entry>
12863        <indexterm>
12864         <primary>regr_sxy</primary>
12865        </indexterm>
12866        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12867       </entry>
12868       <entry>
12869        <type>double precision</type>
12870       </entry>
12871       <entry>
12872        <type>double precision</type>
12873       </entry>
12874       <entry><literal>sum(<replaceable
12875       class="parameter">X</replaceable>*<replaceable
12876       class="parameter">Y</replaceable>) - sum(<replaceable
12877       class="parameter">X</replaceable>) * sum(<replaceable
12878       class="parameter">Y</replaceable>)/<replaceable
12879       class="parameter">N</replaceable></literal> (<quote>sum of
12880       products</quote> of independent times dependent
12881       variable)</entry>
12882      </row>
12883
12884      <row>
12885       <entry>
12886        <indexterm>
12887         <primary>regr_syy</primary>
12888        </indexterm>
12889        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
12890       </entry>
12891       <entry>
12892        <type>double precision</type>
12893       </entry>
12894       <entry>
12895        <type>double precision</type>
12896       </entry>
12897       <entry><literal>sum(<replaceable
12898       class="parameter">Y</replaceable>^2) - sum(<replaceable
12899       class="parameter">Y</replaceable>)^2/<replaceable
12900       class="parameter">N</replaceable></literal> (<quote>sum of
12901       squares</quote> of the dependent variable)</entry>
12902      </row>
12903
12904      <row>
12905       <entry>
12906        <indexterm>
12907         <primary>standard deviation</primary>
12908        </indexterm>
12909        <indexterm>
12910         <primary>stddev</primary>
12911        </indexterm>
12912        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
12913       </entry>
12914       <entry>
12915        <type>smallint</type>, <type>int</type>,
12916        <type>bigint</type>, <type>real</type>, <type>double
12917        precision</type>, or <type>numeric</type>
12918       </entry>
12919       <entry>
12920        <type>double precision</type> for floating-point arguments,
12921        otherwise <type>numeric</type>
12922       </entry>
12923       <entry>historical alias for <function>stddev_samp</function></entry>
12924      </row>
12925
12926      <row>
12927       <entry>
12928        <indexterm>
12929         <primary>standard deviation</primary>
12930         <secondary>population</secondary>
12931        </indexterm>
12932        <indexterm>
12933         <primary>stddev_pop</primary>
12934        </indexterm>
12935        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
12936       </entry>
12937       <entry>
12938        <type>smallint</type>, <type>int</type>,
12939        <type>bigint</type>, <type>real</type>, <type>double
12940        precision</type>, or <type>numeric</type>
12941       </entry>
12942       <entry>
12943        <type>double precision</type> for floating-point arguments,
12944        otherwise <type>numeric</type>
12945       </entry>
12946       <entry>population standard deviation of the input values</entry>
12947      </row>
12948
12949      <row>
12950       <entry>
12951        <indexterm>
12952         <primary>standard deviation</primary>
12953         <secondary>sample</secondary>
12954        </indexterm>
12955        <indexterm>
12956         <primary>stddev_samp</primary>
12957        </indexterm>
12958        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
12959       </entry>
12960       <entry>
12961        <type>smallint</type>, <type>int</type>,
12962        <type>bigint</type>, <type>real</type>, <type>double
12963        precision</type>, or <type>numeric</type>
12964       </entry>
12965       <entry>
12966        <type>double precision</type> for floating-point arguments,
12967        otherwise <type>numeric</type>
12968       </entry>
12969       <entry>sample standard deviation of the input values</entry>
12970      </row>
12971
12972      <row>
12973       <entry>
12974        <indexterm>
12975         <primary>variance</primary>
12976        </indexterm>
12977        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
12978       </entry>
12979       <entry>
12980        <type>smallint</type>, <type>int</type>,
12981        <type>bigint</type>, <type>real</type>, <type>double
12982        precision</type>, or <type>numeric</type>
12983       </entry>
12984       <entry>
12985        <type>double precision</type> for floating-point arguments,
12986        otherwise <type>numeric</type>
12987       </entry>
12988       <entry>historical alias for <function>var_samp</function></entry>
12989      </row>
12990
12991      <row>
12992       <entry>
12993        <indexterm>
12994         <primary>variance</primary>
12995         <secondary>population</secondary>
12996        </indexterm>
12997        <indexterm>
12998         <primary>var_pop</primary>
12999        </indexterm>
13000        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
13001       </entry>
13002       <entry>
13003        <type>smallint</type>, <type>int</type>,
13004        <type>bigint</type>, <type>real</type>, <type>double
13005        precision</type>, or <type>numeric</type>
13006       </entry>
13007       <entry>
13008        <type>double precision</type> for floating-point arguments,
13009        otherwise <type>numeric</type>
13010       </entry>
13011       <entry>population variance of the input values (square of the population standard deviation)</entry>
13012      </row>
13013
13014      <row>
13015       <entry>
13016        <indexterm>
13017         <primary>variance</primary>
13018         <secondary>sample</secondary>
13019        </indexterm>
13020        <indexterm>
13021         <primary>var_samp</primary>
13022        </indexterm>
13023        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
13024       </entry>
13025       <entry>
13026        <type>smallint</type>, <type>int</type>,
13027        <type>bigint</type>, <type>real</type>, <type>double
13028        precision</type>, or <type>numeric</type>
13029       </entry>
13030       <entry>
13031        <type>double precision</type> for floating-point arguments,
13032        otherwise <type>numeric</type>
13033       </entry>
13034       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
13035      </row>
13036     </tbody>
13037    </tgroup>
13038   </table>
13039
13040   <para>
13041    <xref linkend="functions-orderedset-table"> shows some
13042    aggregate functions that use the <firstterm>ordered-set aggregate</>
13043    syntax.  These functions are sometimes referred to as <quote>inverse
13044    distribution</> functions.
13045   </para>
13046
13047   <indexterm>
13048    <primary>ordered-set aggregate</primary>
13049    <secondary>built-in</secondary>
13050   </indexterm>
13051   <indexterm>
13052    <primary>inverse distribution</primary>
13053   </indexterm>
13054
13055   <table id="functions-orderedset-table">
13056    <title>Ordered-Set Aggregate Functions</title>
13057
13058    <tgroup cols="5">
13059     <thead>
13060      <row>
13061       <entry>Function</entry>
13062       <entry>Direct Argument Type(s)</entry>
13063       <entry>Aggregated Argument Type(s)</entry>
13064       <entry>Return Type</entry>
13065       <entry>Description</entry>
13066      </row>
13067     </thead>
13068
13069     <tbody>
13070
13071      <row>
13072       <entry>
13073        <indexterm>
13074         <primary>mode</primary>
13075         <secondary>statistical</secondary>
13076        </indexterm>
13077        <function>mode() WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
13078       </entry>
13079       <entry>
13080       </entry>
13081       <entry>
13082        any sortable type
13083       </entry>
13084       <entry>
13085        same as sort expression
13086       </entry>
13087       <entry>
13088        returns the most frequent input value (arbitrarily choosing the first
13089        one if there are multiple equally-frequent results)
13090       </entry>
13091      </row>
13092
13093      <row>
13094       <entry>
13095        <indexterm>
13096         <primary>percentile</primary>
13097         <secondary>continuous</secondary>
13098        </indexterm>
13099        <indexterm>
13100         <primary>median</primary>
13101        </indexterm>
13102        <function>percentile_cont(<replaceable class="parameter">fraction</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
13103       </entry>
13104       <entry>
13105        <type>double precision</type>
13106       </entry>
13107       <entry>
13108        <type>double precision</type> or <type>interval</type>
13109       </entry>
13110       <entry>
13111        same as sort expression
13112       </entry>
13113       <entry>
13114        continuous percentile: returns a value corresponding to the specified
13115        fraction in the ordering, interpolating between adjacent input items if
13116        needed
13117       </entry>
13118      </row>
13119
13120      <row>
13121       <entry>
13122        <function>percentile_cont(<replaceable class="parameter">fractions</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
13123       </entry>
13124       <entry>
13125        <type>double precision[]</type>
13126       </entry>
13127       <entry>
13128        <type>double precision</type> or <type>interval</type>
13129       </entry>
13130       <entry>
13131        array of sort expression's type
13132       </entry>
13133       <entry>
13134        multiple continuous percentile: returns an array of results matching
13135        the shape of the <literal>fractions</literal> parameter, with each
13136        non-null element replaced by the value corresponding to that percentile
13137       </entry>
13138      </row>
13139
13140      <row>
13141       <entry>
13142        <indexterm>
13143         <primary>percentile</primary>
13144         <secondary>discrete</secondary>
13145        </indexterm>
13146        <function>percentile_disc(<replaceable class="parameter">fraction</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
13147       </entry>
13148       <entry>
13149        <type>double precision</type>
13150       </entry>
13151       <entry>
13152        any sortable type
13153       </entry>
13154       <entry>
13155        same as sort expression
13156       </entry>
13157       <entry>
13158        discrete percentile: returns the first input value whose position in
13159        the ordering equals or exceeds the specified fraction
13160       </entry>
13161      </row>
13162
13163      <row>
13164       <entry>
13165        <function>percentile_disc(<replaceable class="parameter">fractions</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
13166       </entry>
13167       <entry>
13168        <type>double precision[]</type>
13169       </entry>
13170       <entry>
13171        any sortable type
13172       </entry>
13173       <entry>
13174        array of sort expression's type
13175       </entry>
13176       <entry>
13177        multiple discrete percentile: returns an array of results matching the
13178        shape of the <literal>fractions</literal> parameter, with each non-null
13179        element replaced by the input value corresponding to that percentile
13180       </entry>
13181      </row>
13182
13183     </tbody>
13184    </tgroup>
13185   </table>
13186
13187   <para>
13188    All the aggregates listed in <xref linkend="functions-orderedset-table">
13189    ignore null values in their sorted input.  For those that take
13190    a <replaceable>fraction</replaceable> parameter, the fraction value must be
13191    between 0 and 1; an error is thrown if not.  However, a null fraction value
13192    simply produces a null result.
13193   </para>
13194
13195   <indexterm>
13196    <primary>hypothetical-set aggregate</primary>
13197    <secondary>built-in</secondary>
13198   </indexterm>
13199
13200   <para>
13201    Each of the aggregates listed in
13202    <xref linkend="functions-hypothetical-table"> is associated with a
13203    window function of the same name defined in
13204    <xref linkend="functions-window">.  In each case, the aggregate result
13205    is the value that the associated window function would have
13206    returned for the <quote>hypothetical</> row constructed from
13207    <replaceable>args</replaceable>, if such a row had been added to the sorted
13208    group of rows computed from the <replaceable>sorted_args</replaceable>.
13209   </para>
13210
13211   <table id="functions-hypothetical-table">
13212    <title>Hypothetical-Set Aggregate Functions</title>
13213
13214    <tgroup cols="5">
13215     <thead>
13216      <row>
13217       <entry>Function</entry>
13218       <entry>Direct Argument Type(s)</entry>
13219       <entry>Aggregated Argument Type(s)</entry>
13220       <entry>Return Type</entry>
13221       <entry>Description</entry>
13222      </row>
13223     </thead>
13224
13225     <tbody>
13226
13227      <row>
13228       <entry>
13229        <indexterm>
13230         <primary>rank</primary>
13231         <secondary>hypothetical</secondary>
13232        </indexterm>
13233        <function>rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
13234       </entry>
13235       <entry>
13236        <literal>VARIADIC</> <type>"any"</type>
13237       </entry>
13238       <entry>
13239        <literal>VARIADIC</> <type>"any"</type>
13240       </entry>
13241       <entry>
13242        <type>bigint</type>
13243       </entry>
13244       <entry>
13245        rank of the hypothetical row, with gaps for duplicate rows
13246       </entry>
13247      </row>
13248
13249      <row>
13250       <entry>
13251        <indexterm>
13252         <primary>dense_rank</primary>
13253         <secondary>hypothetical</secondary>
13254        </indexterm>
13255        <function>dense_rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
13256       </entry>
13257       <entry>
13258        <literal>VARIADIC</> <type>"any"</type>
13259       </entry>
13260       <entry>
13261        <literal>VARIADIC</> <type>"any"</type>
13262       </entry>
13263       <entry>
13264        <type>bigint</type>
13265       </entry>
13266       <entry>
13267        rank of the hypothetical row, without gaps
13268       </entry>
13269      </row>
13270
13271      <row>
13272       <entry>
13273        <indexterm>
13274         <primary>percent_rank</primary>
13275         <secondary>hypothetical</secondary>
13276        </indexterm>
13277        <function>percent_rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
13278       </entry>
13279       <entry>
13280        <literal>VARIADIC</> <type>"any"</type>
13281       </entry>
13282       <entry>
13283        <literal>VARIADIC</> <type>"any"</type>
13284       </entry>
13285       <entry>
13286        <type>double precision</type>
13287       </entry>
13288       <entry>
13289        relative rank of the hypothetical row, ranging from 0 to 1
13290       </entry>
13291      </row>
13292
13293      <row>
13294       <entry>
13295        <indexterm>
13296         <primary>cume_dist</primary>
13297         <secondary>hypothetical</secondary>
13298        </indexterm>
13299        <function>cume_dist(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
13300       </entry>
13301       <entry>
13302        <literal>VARIADIC</> <type>"any"</type>
13303       </entry>
13304       <entry>
13305        <literal>VARIADIC</> <type>"any"</type>
13306       </entry>
13307       <entry>
13308        <type>double precision</type>
13309       </entry>
13310       <entry>
13311        relative rank of the hypothetical row, ranging from
13312        1/<replaceable>N</> to 1
13313       </entry>
13314      </row>
13315
13316     </tbody>
13317    </tgroup>
13318   </table>
13319
13320   <para>
13321    For each of these hypothetical-set aggregates, the list of direct arguments
13322    given in <replaceable>args</replaceable> must match the number and types of
13323    the aggregated arguments given in <replaceable>sorted_args</replaceable>.
13324    Unlike most built-in aggregates, these aggregates are not strict, that is
13325    they do not drop input rows containing nulls.  Null values sort according
13326    to the rule specified in the <literal>ORDER BY</> clause.
13327   </para>
13328
13329  </sect1>
13330
13331  <sect1 id="functions-window">
13332   <title>Window Functions</title>
13333
13334   <indexterm zone="functions-window">
13335    <primary>window function</primary>
13336    <secondary>built-in</secondary>
13337   </indexterm>
13338
13339   <para>
13340    <firstterm>Window functions</firstterm> provide the ability to perform
13341    calculations across sets of rows that are related to the current query
13342    row.  See <xref linkend="tutorial-window"> for an introduction to this
13343    feature, and <xref linkend="syntax-window-functions"> for syntax
13344    details.
13345   </para>
13346
13347   <para>
13348    The built-in window functions are listed in
13349    <xref linkend="functions-window-table">.  Note that these functions
13350    <emphasis>must</> be invoked using window function syntax; that is an
13351    <literal>OVER</> clause is required.
13352   </para>
13353
13354   <para>
13355    In addition to these functions, any built-in or user-defined normal
13356    aggregate function (but not ordered-set or hypothetical-set aggregates)
13357    can be used as a window function; see
13358    <xref linkend="functions-aggregate"> for a list of the built-in aggregates.
13359    Aggregate functions act as window functions only when an <literal>OVER</>
13360    clause follows the call; otherwise they act as regular aggregates.
13361   </para>
13362
13363   <table id="functions-window-table">
13364    <title>General-Purpose Window Functions</title>
13365
13366    <tgroup cols="3">
13367     <thead>
13368      <row>
13369       <entry>Function</entry>
13370       <entry>Return Type</entry>
13371       <entry>Description</entry>
13372      </row>
13373     </thead>
13374
13375     <tbody>
13376      <row>
13377       <entry>
13378        <indexterm>
13379         <primary>row_number</primary>
13380        </indexterm>
13381        <function>row_number()</function>
13382       </entry>
13383       <entry>
13384        <type>bigint</type>
13385       </entry>
13386       <entry>number of the current row within its partition, counting from 1</entry>
13387      </row>
13388
13389      <row>
13390       <entry>
13391        <indexterm>
13392         <primary>rank</primary>
13393        </indexterm>
13394        <function>rank()</function>
13395       </entry>
13396       <entry>
13397        <type>bigint</type>
13398       </entry>
13399       <entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
13400      </row>
13401
13402      <row>
13403       <entry>
13404        <indexterm>
13405         <primary>dense_rank</primary>
13406        </indexterm>
13407        <function>dense_rank()</function>
13408       </entry>
13409       <entry>
13410        <type>bigint</type>
13411       </entry>
13412       <entry>rank of the current row without gaps; this function counts peer groups</entry>
13413      </row>
13414
13415      <row>
13416       <entry>
13417        <indexterm>
13418         <primary>percent_rank</primary>
13419        </indexterm>
13420        <function>percent_rank()</function>
13421       </entry>
13422       <entry>
13423        <type>double precision</type>
13424       </entry>
13425       <entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
13426      </row>
13427
13428      <row>
13429       <entry>
13430        <indexterm>
13431         <primary>cume_dist</primary>
13432        </indexterm>
13433        <function>cume_dist()</function>
13434       </entry>
13435       <entry>
13436        <type>double precision</type>
13437       </entry>
13438       <entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
13439      </row>
13440
13441      <row>
13442       <entry>
13443        <indexterm>
13444         <primary>ntile</primary>
13445        </indexterm>
13446        <function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</>)</function>
13447       </entry>
13448       <entry>
13449        <type>integer</type>
13450       </entry>
13451       <entry>integer ranging from 1 to the argument value, dividing the
13452        partition as equally as possible</entry>
13453      </row>
13454
13455      <row>
13456       <entry>
13457        <indexterm>
13458         <primary>lag</primary>
13459        </indexterm>
13460        <function>
13461          lag(<replaceable class="parameter">value</replaceable> <type>any</>
13462              [, <replaceable class="parameter">offset</replaceable> <type>integer</>
13463              [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
13464        </function>
13465       </entry>
13466       <entry>
13467        <type>same type as <replaceable class="parameter">value</replaceable></type>
13468       </entry>
13469       <entry>
13470        returns <replaceable class="parameter">value</replaceable> evaluated at
13471        the row that is <replaceable class="parameter">offset</replaceable>
13472        rows before the current row within the partition; if there is no such
13473        row, instead return <replaceable class="parameter">default</replaceable>.
13474        Both <replaceable class="parameter">offset</replaceable> and
13475        <replaceable class="parameter">default</replaceable> are evaluated
13476        with respect to the current row.  If omitted,
13477        <replaceable class="parameter">offset</replaceable> defaults to 1 and
13478        <replaceable class="parameter">default</replaceable> to null
13479       </entry>
13480      </row>
13481
13482      <row>
13483       <entry>
13484        <indexterm>
13485         <primary>lead</primary>
13486        </indexterm>
13487        <function>
13488          lead(<replaceable class="parameter">value</replaceable> <type>any</>
13489               [, <replaceable class="parameter">offset</replaceable> <type>integer</>
13490               [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
13491        </function>
13492       </entry>
13493       <entry>
13494        <type>same type as <replaceable class="parameter">value</replaceable></type>
13495       </entry>
13496       <entry>
13497        returns <replaceable class="parameter">value</replaceable> evaluated at
13498        the row that is <replaceable class="parameter">offset</replaceable>
13499        rows after the current row within the partition; if there is no such
13500        row, instead return <replaceable class="parameter">default</replaceable>.
13501        Both <replaceable class="parameter">offset</replaceable> and
13502        <replaceable class="parameter">default</replaceable> are evaluated
13503        with respect to the current row.  If omitted,
13504        <replaceable class="parameter">offset</replaceable> defaults to 1 and
13505        <replaceable class="parameter">default</replaceable> to null
13506       </entry>
13507      </row>
13508
13509      <row>
13510       <entry>
13511        <indexterm>
13512         <primary>first_value</primary>
13513        </indexterm>
13514        <function>first_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
13515       </entry>
13516       <entry>
13517        <type>same type as <replaceable class="parameter">value</replaceable></type>
13518       </entry>
13519       <entry>
13520        returns <replaceable class="parameter">value</replaceable> evaluated
13521        at the row that is the first row of the window frame
13522       </entry>
13523      </row>
13524
13525      <row>
13526       <entry>
13527        <indexterm>
13528         <primary>last_value</primary>
13529        </indexterm>
13530        <function>last_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
13531       </entry>
13532       <entry>
13533        <type>same type as <replaceable class="parameter">value</replaceable></type>
13534       </entry>
13535       <entry>
13536        returns <replaceable class="parameter">value</replaceable> evaluated
13537        at the row that is the last row of the window frame
13538       </entry>
13539      </row>
13540
13541      <row>
13542       <entry>
13543        <indexterm>
13544         <primary>nth_value</primary>
13545        </indexterm>
13546        <function>
13547          nth_value(<replaceable class="parameter">value</replaceable> <type>any</>, <replaceable class="parameter">nth</replaceable> <type>integer</>)
13548        </function>
13549       </entry>
13550       <entry>
13551        <type>same type as <replaceable class="parameter">value</replaceable></type>
13552       </entry>
13553       <entry>
13554        returns <replaceable class="parameter">value</replaceable> evaluated
13555        at the row that is the <replaceable class="parameter">nth</replaceable>
13556        row of the window frame (counting from 1); null if no such row
13557       </entry>
13558      </row>
13559     </tbody>
13560    </tgroup>
13561   </table>
13562
13563   <para>
13564    All of the functions listed in
13565    <xref linkend="functions-window-table"> depend on the sort ordering
13566    specified by the <literal>ORDER BY</> clause of the associated window
13567    definition.  Rows that are not distinct in the <literal>ORDER BY</>
13568    ordering are said to be <firstterm>peers</>; the four ranking functions
13569    are defined so that they give the same answer for any two peer rows.
13570   </para>
13571
13572   <para>
13573    Note that <function>first_value</>, <function>last_value</>, and
13574    <function>nth_value</> consider only the rows within the <quote>window
13575    frame</>, which by default contains the rows from the start of the
13576    partition through the last peer of the current row.  This is
13577    likely to give unhelpful results for <function>last_value</> and
13578    sometimes also <function>nth_value</>.  You can redefine the frame by
13579    adding a suitable frame specification (<literal>RANGE</> or
13580    <literal>ROWS</>) to the <literal>OVER</> clause.
13581    See <xref linkend="syntax-window-functions"> for more information
13582    about frame specifications.
13583   </para>
13584
13585   <para>
13586    When an aggregate function is used as a window function, it aggregates
13587    over the rows within the current row's window frame.
13588    An aggregate used with <literal>ORDER BY</> and the default window frame
13589    definition produces a <quote>running sum</> type of behavior, which may or
13590    may not be what's wanted.  To obtain
13591    aggregation over the whole partition, omit <literal>ORDER BY</> or use
13592    <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
13593    Other frame specifications can be used to obtain other effects.
13594   </para>
13595
13596   <note>
13597    <para>
13598     The SQL standard defines a <literal>RESPECT NULLS</> or
13599     <literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
13600     <function>first_value</>, <function>last_value</>, and
13601     <function>nth_value</>.  This is not implemented in
13602     <productname>PostgreSQL</productname>: the behavior is always the
13603     same as the standard's default, namely <literal>RESPECT NULLS</>.
13604     Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
13605     option for <function>nth_value</> is not implemented: only the
13606     default <literal>FROM FIRST</> behavior is supported.  (You can achieve
13607     the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
13608     ordering.)
13609    </para>
13610   </note>
13611
13612  </sect1>
13613
13614  <sect1 id="functions-subquery">
13615   <title>Subquery Expressions</title>
13616
13617   <indexterm>
13618    <primary>EXISTS</primary>
13619   </indexterm>
13620
13621   <indexterm>
13622    <primary>IN</primary>
13623   </indexterm>
13624
13625   <indexterm>
13626    <primary>NOT IN</primary>
13627   </indexterm>
13628
13629   <indexterm>
13630    <primary>ANY</primary>
13631   </indexterm>
13632
13633   <indexterm>
13634    <primary>ALL</primary>
13635   </indexterm>
13636
13637   <indexterm>
13638    <primary>SOME</primary>
13639   </indexterm>
13640
13641   <indexterm>
13642    <primary>subquery</primary>
13643   </indexterm>
13644
13645   <para>
13646    This section describes the <acronym>SQL</acronym>-compliant subquery
13647    expressions available in <productname>PostgreSQL</productname>.
13648    All of the expression forms documented in this section return
13649    Boolean (true/false) results.
13650   </para>
13651
13652   <sect2 id="functions-subquery-exists">
13653    <title><literal>EXISTS</literal></title>
13654
13655 <synopsis>
13656 EXISTS (<replaceable>subquery</replaceable>)
13657 </synopsis>
13658
13659   <para>
13660    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
13661    or <firstterm>subquery</firstterm>.  The
13662    subquery is evaluated to determine whether it returns any rows.
13663    If it returns at least one row, the result of <token>EXISTS</token> is
13664    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
13665    is <quote>false</>.
13666   </para>
13667
13668   <para>
13669    The subquery can refer to variables from the surrounding query,
13670    which will act as constants during any one evaluation of the subquery.
13671   </para>
13672
13673   <para>
13674    The subquery will generally only be executed long enough to determine
13675    whether at least one row is returned, not all the way to completion.
13676    It is unwise to write a subquery that has side effects (such as
13677    calling sequence functions); whether the side effects occur
13678    might be unpredictable.
13679   </para>
13680
13681   <para>
13682    Since the result depends only on whether any rows are returned,
13683    and not on the contents of those rows, the output list of the
13684    subquery is normally unimportant.  A common coding convention is
13685    to write all <literal>EXISTS</> tests in the form
13686    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
13687    this rule however, such as subqueries that use <token>INTERSECT</token>.
13688   </para>
13689
13690   <para>
13691    This simple example is like an inner join on <literal>col2</>, but
13692    it produces at most one output row for each <literal>tab1</> row,
13693    even if there are several matching <literal>tab2</> rows:
13694 <screen>
13695 SELECT col1
13696 FROM tab1
13697 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
13698 </screen>
13699   </para>
13700   </sect2>
13701
13702   <sect2 id="functions-subquery-in">
13703    <title><literal>IN</literal></title>
13704
13705 <synopsis>
13706 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
13707 </synopsis>
13708
13709   <para>
13710    The right-hand side is a parenthesized
13711    subquery, which must return exactly one column.  The left-hand expression
13712    is evaluated and compared to each row of the subquery result.
13713    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
13714    The result is <quote>false</> if no equal row is found (including the
13715    case where the subquery returns no rows).
13716   </para>
13717
13718   <para>
13719    Note that if the left-hand expression yields null, or if there are
13720    no equal right-hand values and at least one right-hand row yields
13721    null, the result of the <token>IN</token> construct will be null, not false.
13722    This is in accordance with SQL's normal rules for Boolean combinations
13723    of null values.
13724   </para>
13725
13726   <para>
13727    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
13728    be evaluated completely.
13729   </para>
13730
13731 <synopsis>
13732 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
13733 </synopsis>
13734
13735   <para>
13736    The left-hand side of this form of <token>IN</token> is a row constructor,
13737    as described in <xref linkend="sql-syntax-row-constructors">.
13738    The right-hand side is a parenthesized
13739    subquery, which must return exactly as many columns as there are
13740    expressions in the left-hand row.  The left-hand expressions are
13741    evaluated and compared row-wise to each row of the subquery result.
13742    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
13743    The result is <quote>false</> if no equal row is found (including the
13744    case where the subquery returns no rows).
13745   </para>
13746
13747   <para>
13748    As usual, null values in the rows are combined per
13749    the normal rules of SQL Boolean expressions.  Two rows are considered
13750    equal if all their corresponding members are non-null and equal; the rows
13751    are unequal if any corresponding members are non-null and unequal;
13752    otherwise the result of that row comparison is unknown (null).
13753    If all the per-row results are either unequal or null, with at least one
13754    null, then the result of <token>IN</token> is null.
13755   </para>
13756   </sect2>
13757
13758   <sect2 id="functions-subquery-notin">
13759    <title><literal>NOT IN</literal></title>
13760
13761 <synopsis>
13762 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
13763 </synopsis>
13764
13765   <para>
13766    The right-hand side is a parenthesized
13767    subquery, which must return exactly one column.  The left-hand expression
13768    is evaluated and compared to each row of the subquery result.
13769    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
13770    are found (including the case where the subquery returns no rows).
13771    The result is <quote>false</> if any equal row is found.
13772   </para>
13773
13774   <para>
13775    Note that if the left-hand expression yields null, or if there are
13776    no equal right-hand values and at least one right-hand row yields
13777    null, the result of the <token>NOT IN</token> construct will be null, not true.
13778    This is in accordance with SQL's normal rules for Boolean combinations
13779    of null values.
13780   </para>
13781
13782   <para>
13783    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
13784    be evaluated completely.
13785   </para>
13786
13787 <synopsis>
13788 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
13789 </synopsis>
13790
13791   <para>
13792    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
13793    as described in <xref linkend="sql-syntax-row-constructors">.
13794    The right-hand side is a parenthesized
13795    subquery, which must return exactly as many columns as there are
13796    expressions in the left-hand row.  The left-hand expressions are
13797    evaluated and compared row-wise to each row of the subquery result.
13798    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
13799    are found (including the case where the subquery returns no rows).
13800    The result is <quote>false</> if any equal row is found.
13801   </para>
13802
13803   <para>
13804    As usual, null values in the rows are combined per
13805    the normal rules of SQL Boolean expressions.  Two rows are considered
13806    equal if all their corresponding members are non-null and equal; the rows
13807    are unequal if any corresponding members are non-null and unequal;
13808    otherwise the result of that row comparison is unknown (null).
13809    If all the per-row results are either unequal or null, with at least one
13810    null, then the result of <token>NOT IN</token> is null.
13811   </para>
13812   </sect2>
13813
13814   <sect2 id="functions-subquery-any-some">
13815    <title><literal>ANY</literal>/<literal>SOME</literal></title>
13816
13817 <synopsis>
13818 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
13819 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
13820 </synopsis>
13821
13822   <para>
13823    The right-hand side is a parenthesized
13824    subquery, which must return exactly one column.  The left-hand expression
13825    is evaluated and compared to each row of the subquery result using the
13826    given <replaceable>operator</replaceable>, which must yield a Boolean
13827    result.
13828    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
13829    The result is <quote>false</> if no true result is found (including the
13830    case where the subquery returns no rows).
13831   </para>
13832
13833   <para>
13834    <token>SOME</token> is a synonym for <token>ANY</token>.
13835    <token>IN</token> is equivalent to <literal>= ANY</literal>.
13836   </para>
13837
13838   <para>
13839    Note that if there are no successes and at least one right-hand row yields
13840    null for the operator's result, the result of the <token>ANY</token> construct
13841    will be null, not false.
13842    This is in accordance with SQL's normal rules for Boolean combinations
13843    of null values.
13844   </para>
13845
13846   <para>
13847    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
13848    be evaluated completely.
13849   </para>
13850
13851 <synopsis>
13852 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
13853 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
13854 </synopsis>
13855
13856   <para>
13857    The left-hand side of this form of <token>ANY</token> is a row constructor,
13858    as described in <xref linkend="sql-syntax-row-constructors">.
13859    The right-hand side is a parenthesized
13860    subquery, which must return exactly as many columns as there are
13861    expressions in the left-hand row.  The left-hand expressions are
13862    evaluated and compared row-wise to each row of the subquery result,
13863    using the given <replaceable>operator</replaceable>.
13864    The result of <token>ANY</token> is <quote>true</> if the comparison
13865    returns true for any subquery row.
13866    The result is <quote>false</> if the comparison returns false for every
13867    subquery row (including the case where the subquery returns no
13868    rows).
13869    The result is NULL if the comparison does not return true for any row,
13870    and it returns NULL for at least one row.
13871   </para>
13872
13873   <para>
13874    See <xref linkend="row-wise-comparison"> for details about the meaning
13875    of a row constructor comparison.
13876   </para>
13877   </sect2>
13878
13879   <sect2 id="functions-subquery-all">
13880    <title><literal>ALL</literal></title>
13881
13882 <synopsis>
13883 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
13884 </synopsis>
13885
13886   <para>
13887    The right-hand side is a parenthesized
13888    subquery, which must return exactly one column.  The left-hand expression
13889    is evaluated and compared to each row of the subquery result using the
13890    given <replaceable>operator</replaceable>, which must yield a Boolean
13891    result.
13892    The result of <token>ALL</token> is <quote>true</> if all rows yield true
13893    (including the case where the subquery returns no rows).
13894    The result is <quote>false</> if any false result is found.
13895    The result is NULL if the comparison does not return false for any row,
13896    and it returns NULL for at least one row.
13897   </para>
13898
13899   <para>
13900    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
13901   </para>
13902
13903   <para>
13904    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
13905    be evaluated completely.
13906   </para>
13907
13908 <synopsis>
13909 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
13910 </synopsis>
13911
13912   <para>
13913    The left-hand side of this form of <token>ALL</token> is a row constructor,
13914    as described in <xref linkend="sql-syntax-row-constructors">.
13915    The right-hand side is a parenthesized
13916    subquery, which must return exactly as many columns as there are
13917    expressions in the left-hand row.  The left-hand expressions are
13918    evaluated and compared row-wise to each row of the subquery result,
13919    using the given <replaceable>operator</replaceable>.
13920    The result of <token>ALL</token> is <quote>true</> if the comparison
13921    returns true for all subquery rows (including the
13922    case where the subquery returns no rows).
13923    The result is <quote>false</> if the comparison returns false for any
13924    subquery row.
13925    The result is NULL if the comparison does not return false for any
13926    subquery row, and it returns NULL for at least one row.
13927   </para>
13928
13929   <para>
13930    See <xref linkend="row-wise-comparison"> for details about the meaning
13931    of a row constructor comparison.
13932   </para>
13933   </sect2>
13934
13935   <sect2>
13936    <title>Single-row Comparison</title>
13937
13938    <indexterm zone="functions-subquery">
13939     <primary>comparison</primary>
13940     <secondary>subquery result row</secondary>
13941    </indexterm>
13942
13943 <synopsis>
13944 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
13945 </synopsis>
13946
13947   <para>
13948    The left-hand side is a row constructor,
13949    as described in <xref linkend="sql-syntax-row-constructors">.
13950    The right-hand side is a parenthesized subquery, which must return exactly
13951    as many columns as there are expressions in the left-hand row. Furthermore,
13952    the subquery cannot return more than one row.  (If it returns zero rows,
13953    the result is taken to be null.)  The left-hand side is evaluated and
13954    compared row-wise to the single subquery result row.
13955   </para>
13956
13957   <para>
13958    See <xref linkend="row-wise-comparison"> for details about the meaning
13959    of a row constructor comparison.
13960   </para>
13961   </sect2>
13962  </sect1>
13963
13964
13965  <sect1 id="functions-comparisons">
13966   <title>Row and Array Comparisons</title>
13967
13968   <indexterm>
13969    <primary>IN</primary>
13970   </indexterm>
13971
13972   <indexterm>
13973    <primary>NOT IN</primary>
13974   </indexterm>
13975
13976   <indexterm>
13977    <primary>ANY</primary>
13978   </indexterm>
13979
13980   <indexterm>
13981    <primary>ALL</primary>
13982   </indexterm>
13983
13984   <indexterm>
13985    <primary>SOME</primary>
13986   </indexterm>
13987
13988   <indexterm>
13989    <primary>composite type</primary>
13990    <secondary>comparison</secondary>
13991   </indexterm>
13992
13993   <indexterm>
13994    <primary>row-wise comparison</primary>
13995   </indexterm>
13996
13997   <indexterm>
13998    <primary>comparison</primary>
13999    <secondary>composite type</secondary>
14000   </indexterm>
14001
14002   <indexterm>
14003    <primary>comparison</primary>
14004    <secondary>row constructor</secondary>
14005   </indexterm>
14006
14007   <indexterm>
14008    <primary>IS DISTINCT FROM</primary>
14009   </indexterm>
14010
14011   <indexterm>
14012    <primary>IS NOT DISTINCT FROM</primary>
14013   </indexterm>
14014
14015   <para>
14016    This section describes several specialized constructs for making
14017    multiple comparisons between groups of values.  These forms are
14018    syntactically related to the subquery forms of the previous section,
14019    but do not involve subqueries.
14020    The forms involving array subexpressions are
14021    <productname>PostgreSQL</productname> extensions; the rest are
14022    <acronym>SQL</acronym>-compliant.
14023    All of the expression forms documented in this section return
14024    Boolean (true/false) results.
14025   </para>
14026
14027   <sect2>
14028    <title><literal>IN</literal></title>
14029
14030 <synopsis>
14031 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
14032 </synopsis>
14033
14034   <para>
14035    The right-hand side is a parenthesized list
14036    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
14037    result is equal to any of the right-hand expressions.  This is a shorthand
14038    notation for
14039
14040 <synopsis>
14041 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
14042 OR
14043 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
14044 OR
14045 ...
14046 </synopsis>
14047   </para>
14048
14049   <para>
14050    Note that if the left-hand expression yields null, or if there are
14051    no equal right-hand values and at least one right-hand expression yields
14052    null, the result of the <token>IN</token> construct will be null, not false.
14053    This is in accordance with SQL's normal rules for Boolean combinations
14054    of null values.
14055   </para>
14056   </sect2>
14057
14058   <sect2>
14059    <title><literal>NOT IN</literal></title>
14060
14061 <synopsis>
14062 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
14063 </synopsis>
14064
14065   <para>
14066    The right-hand side is a parenthesized list
14067    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
14068    result is unequal to all of the right-hand expressions.  This is a shorthand
14069    notation for
14070
14071 <synopsis>
14072 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
14073 AND
14074 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
14075 AND
14076 ...
14077 </synopsis>
14078   </para>
14079
14080   <para>
14081    Note that if the left-hand expression yields null, or if there are
14082    no equal right-hand values and at least one right-hand expression yields
14083    null, the result of the <token>NOT IN</token> construct will be null, not true
14084    as one might naively expect.
14085    This is in accordance with SQL's normal rules for Boolean combinations
14086    of null values.
14087   </para>
14088
14089   <tip>
14090   <para>
14091    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
14092    cases.  However, null values are much more likely to trip up the novice when
14093    working with <token>NOT IN</token> than when working with <token>IN</token>.
14094    It is best to express your condition positively if possible.
14095   </para>
14096   </tip>
14097   </sect2>
14098
14099   <sect2>
14100    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
14101
14102 <synopsis>
14103 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
14104 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
14105 </synopsis>
14106
14107   <para>
14108    The right-hand side is a parenthesized expression, which must yield an
14109    array value.
14110    The left-hand expression
14111    is evaluated and compared to each element of the array using the
14112    given <replaceable>operator</replaceable>, which must yield a Boolean
14113    result.
14114    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
14115    The result is <quote>false</> if no true result is found (including the
14116    case where the array has zero elements).
14117   </para>
14118
14119   <para>
14120    If the array expression yields a null array, the result of
14121    <token>ANY</token> will be null.  If the left-hand expression yields null,
14122    the result of <token>ANY</token> is ordinarily null (though a non-strict
14123    comparison operator could possibly yield a different result).
14124    Also, if the right-hand array contains any null elements and no true
14125    comparison result is obtained, the result of <token>ANY</token>
14126    will be null, not false (again, assuming a strict comparison operator).
14127    This is in accordance with SQL's normal rules for Boolean combinations
14128    of null values.
14129   </para>
14130
14131   <para>
14132    <token>SOME</token> is a synonym for <token>ANY</token>.
14133   </para>
14134   </sect2>
14135
14136   <sect2>
14137    <title><literal>ALL</literal> (array)</title>
14138
14139 <synopsis>
14140 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
14141 </synopsis>
14142
14143   <para>
14144    The right-hand side is a parenthesized expression, which must yield an
14145    array value.
14146    The left-hand expression
14147    is evaluated and compared to each element of the array using the
14148    given <replaceable>operator</replaceable>, which must yield a Boolean
14149    result.
14150    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
14151    (including the case where the array has zero elements).
14152    The result is <quote>false</> if any false result is found.
14153   </para>
14154
14155   <para>
14156    If the array expression yields a null array, the result of
14157    <token>ALL</token> will be null.  If the left-hand expression yields null,
14158    the result of <token>ALL</token> is ordinarily null (though a non-strict
14159    comparison operator could possibly yield a different result).
14160    Also, if the right-hand array contains any null elements and no false
14161    comparison result is obtained, the result of <token>ALL</token>
14162    will be null, not true (again, assuming a strict comparison operator).
14163    This is in accordance with SQL's normal rules for Boolean combinations
14164    of null values.
14165   </para>
14166   </sect2>
14167
14168   <sect2 id="row-wise-comparison">
14169    <title>Row Constructor Comparison</title>
14170
14171 <synopsis>
14172 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
14173 </synopsis>
14174
14175   <para>
14176    Each side is a row constructor,
14177    as described in <xref linkend="sql-syntax-row-constructors">.
14178    The two row values must have the same number of fields.
14179    Each side is evaluated and they are compared row-wise.  Row constructor
14180    comparisons are allowed when the <replaceable>operator</replaceable> is
14181    <literal>=</>,
14182    <literal>&lt;&gt;</>,
14183    <literal>&lt;</>,
14184    <literal>&lt;=</>,
14185    <literal>&gt;</> or
14186    <literal>&gt;=</>.
14187    Every row element must be of a type which has a default B-tree operator
14188    class or the attempted comparison may generate an error.
14189   </para>
14190
14191   <note>
14192    <para>
14193     Errors related to the number or types of elements might not occur if
14194     the comparison is resolved using earlier columns.
14195    </para>
14196   </note>
14197
14198   <para>
14199    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
14200    from the others.  Two rows are considered
14201    equal if all their corresponding members are non-null and equal; the rows
14202    are unequal if any corresponding members are non-null and unequal;
14203    otherwise the result of the row comparison is unknown (null).
14204   </para>
14205
14206   <para>
14207    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
14208    <literal>&gt;=</> cases, the row elements are compared left-to-right,
14209    stopping as soon as an unequal or null pair of elements is found.
14210    If either of this pair of elements is null, the result of the
14211    row comparison is unknown (null); otherwise comparison of this pair
14212    of elements determines the result.  For example,
14213    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
14214    yields true, not null, because the third pair of elements are not
14215    considered.
14216   </para>
14217
14218   <note>
14219    <para>
14220     Prior to <productname>PostgreSQL</productname> 8.2, the
14221     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
14222     cases were not handled per SQL specification.  A comparison like
14223     <literal>ROW(a,b) &lt; ROW(c,d)</>
14224     was implemented as
14225     <literal>a &lt; c AND b &lt; d</>
14226     whereas the correct behavior is equivalent to
14227     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
14228    </para>
14229   </note>
14230
14231 <synopsis>
14232 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
14233 </synopsis>
14234
14235   <para>
14236    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
14237    but it does not yield null for null inputs.  Instead, any null value is
14238    considered unequal to (distinct from) any non-null value, and any two
14239    nulls are considered equal (not distinct).  Thus the result will
14240    either be true or false, never null.
14241   </para>
14242
14243 <synopsis>
14244 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
14245 </synopsis>
14246
14247   <para>
14248    This construct is similar to a <literal>=</literal> row comparison,
14249    but it does not yield null for null inputs.  Instead, any null value is
14250    considered unequal to (distinct from) any non-null value, and any two
14251    nulls are considered equal (not distinct).  Thus the result will always
14252    be either true or false, never null.
14253   </para>
14254
14255   </sect2>
14256
14257   <sect2 id="composite-type-comparison">
14258    <title>Composite Type Comparison</title>
14259
14260 <synopsis>
14261 <replaceable>record</replaceable> <replaceable>operator</replaceable> <replaceable>record</replaceable>
14262 </synopsis>
14263
14264   <para>
14265    The SQL specification requires row-wise comparison to return NULL if the
14266    result depends on comparing two NULL values or a NULL and a non-NULL.
14267    <productname>PostgreSQL</productname> does this only when comparing the
14268    results of two row constructors (as in
14269    <xref linkend="row-wise-comparison">) or comparing a row constructor
14270    to the output of a subquery (as in <xref linkend="functions-subquery">).
14271    In other contexts where two composite-type values are compared, two
14272    NULL field values are considered equal, and a NULL is considered larger
14273    than a non-NULL.  This is necessary in order to have consistent sorting
14274    and indexing behavior for composite types.
14275   </para>
14276
14277   <para>
14278    Each side is evaluated and they are compared row-wise.  Composite type
14279    comparisons are allowed when the <replaceable>operator</replaceable> is
14280    <literal>=</>,
14281    <literal>&lt;&gt;</>,
14282    <literal>&lt;</>,
14283    <literal>&lt;=</>,
14284    <literal>&gt;</> or
14285    <literal>&gt;=</>,
14286    or has semantics similar to one of these.  (To be specific, an operator
14287    can be a row comparison operator if it is a member of a B-tree operator
14288    class, or is the negator of the <literal>=</> member of a B-tree operator
14289    class.)  The default behavior of the above operators is the same as for
14290    <literal>IS [ NOT ] DISTINCT FROM</literal> for row constructors (see
14291    <xref linkend="row-wise-comparison">).
14292   </para>
14293
14294   <para>
14295    To support matching of rows which include elements without a default
14296    B-tree operator class, the following operators are defined for composite
14297    type comparison:
14298    <literal>*=</>,
14299    <literal>*&lt;&gt;</>,
14300    <literal>*&lt;</>,
14301    <literal>*&lt;=</>,
14302    <literal>*&gt;</>, and
14303    <literal>*&gt;=</>.
14304    These operators compare the internal binary representation of the two
14305    rows.  Two rows might have a different binary representation even
14306    though comparisons of the two rows with the equality operator is true.
14307    The ordering of rows under these comparison operators is deterministic
14308    but not otherwise meaningful.  These operators are used internally for
14309    materialized views and might be useful for other specialized purposes
14310    such as replication but are not intended to be generally useful for
14311    writing queries.
14312   </para>
14313   </sect2>
14314  </sect1>
14315
14316  <sect1 id="functions-srf">
14317   <title>Set Returning Functions</title>
14318
14319   <indexterm zone="functions-srf">
14320    <primary>set returning functions</primary>
14321    <secondary>functions</secondary>
14322   </indexterm>
14323
14324   <indexterm>
14325    <primary>generate_series</primary>
14326   </indexterm>
14327
14328   <para>
14329    This section describes functions that possibly return more than one row.
14330    The most widely used functions in this class are series generating
14331    functions, as detailed in <xref linkend="functions-srf-series"> and
14332    <xref linkend="functions-srf-subscripts">.  Other, more specialized
14333    set-returning functions are described elsewhere in this manual.
14334    See <xref linkend="queries-tablefunctions"> for ways to combine multiple
14335    set-returning functions.
14336   </para>
14337
14338   <table id="functions-srf-series">
14339    <title>Series Generating Functions</title>
14340    <tgroup cols="4">
14341     <thead>
14342      <row>
14343       <entry>Function</entry>
14344       <entry>Argument Type</entry>
14345       <entry>Return Type</entry>
14346       <entry>Description</entry>
14347      </row>
14348     </thead>
14349
14350     <tbody>
14351      <row>
14352       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>)</function></literal></entry>
14353       <entry><type>int</type>, <type>bigint</type> or <type>numeric</type></entry>
14354       <entry><type>setof int</type>, <type>setof bigint</type>, or <type>setof numeric</type> (same as argument type)</entry>
14355       <entry>
14356        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
14357        with a step size of one
14358       </entry>
14359      </row>
14360
14361      <row>
14362       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</function></literal></entry>
14363       <entry><type>int</type>, <type>bigint</type> or <type>numeric</type></entry>
14364       <entry><type>setof int</type>, <type>setof bigint</type> or <type>setof numeric</type> (same as argument type)</entry>
14365       <entry>
14366        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
14367        with a step size of <parameter>step</parameter>
14368       </entry>
14369      </row>
14370
14371      <row>
14372       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</function></literal></entry>
14373       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
14374       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
14375       <entry>
14376        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
14377        with a step size of <parameter>step</parameter>
14378       </entry>
14379      </row>
14380
14381     </tbody>
14382    </tgroup>
14383   </table>
14384
14385   <para>
14386    When <parameter>step</parameter> is positive, zero rows are returned if
14387    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
14388    Conversely, when <parameter>step</parameter> is negative, zero rows are
14389    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
14390    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
14391    for <parameter>step</parameter> to be zero. Some examples follow:
14392 <programlisting>
14393 SELECT * FROM generate_series(2,4);
14394  generate_series
14395 -----------------
14396                2
14397                3
14398                4
14399 (3 rows)
14400
14401 SELECT * FROM generate_series(5,1,-2);
14402  generate_series
14403 -----------------
14404                5
14405                3
14406                1
14407 (3 rows)
14408
14409 SELECT * FROM generate_series(4,3);
14410  generate_series
14411 -----------------
14412 (0 rows)
14413
14414 SELECT generate_series(1.1, 4, 1.3);
14415  generate_series 
14416 -----------------
14417              1.1
14418              2.4
14419              3.7
14420 (3 rows)
14421
14422 -- this example relies on the date-plus-integer operator
14423 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
14424    dates
14425 ------------
14426  2004-02-05
14427  2004-02-12
14428  2004-02-19
14429 (3 rows)
14430
14431 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
14432                               '2008-03-04 12:00', '10 hours');
14433    generate_series   
14434 ---------------------
14435  2008-03-01 00:00:00
14436  2008-03-01 10:00:00
14437  2008-03-01 20:00:00
14438  2008-03-02 06:00:00
14439  2008-03-02 16:00:00
14440  2008-03-03 02:00:00
14441  2008-03-03 12:00:00
14442  2008-03-03 22:00:00
14443  2008-03-04 08:00:00
14444 (9 rows)
14445 </programlisting>
14446   </para>
14447
14448   <table id="functions-srf-subscripts">
14449    <title>Subscript Generating Functions</title>
14450    <tgroup cols="3">
14451     <thead>
14452      <row>
14453       <entry>Function</entry>
14454       <entry>Return Type</entry>
14455       <entry>Description</entry>
14456      </row>
14457     </thead>
14458
14459     <tbody>
14460      <row>
14461       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</function></literal></entry>
14462       <entry><type>setof int</type></entry>
14463       <entry>
14464        Generate a series comprising the given array's subscripts.
14465       </entry>
14466      </row>
14467
14468      <row>
14469       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</function></literal></entry>
14470       <entry><type>setof int</type></entry>
14471       <entry>
14472        Generate a series comprising the given array's subscripts. When
14473        <parameter>reverse</parameter> is true, the series is returned in
14474        reverse order.
14475       </entry>
14476      </row>
14477
14478     </tbody>
14479    </tgroup>
14480   </table>
14481
14482   <indexterm>
14483    <primary>generate_subscripts</primary>
14484   </indexterm>
14485
14486   <para>
14487    <function>generate_subscripts</> is a convenience function that generates
14488    the set of valid subscripts for the specified dimension of the given
14489    array.
14490    Zero rows are returned for arrays that do not have the requested dimension,
14491    or for NULL arrays (but valid subscripts are returned for NULL array
14492    elements).  Some examples follow:
14493 <programlisting>
14494 -- basic usage
14495 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
14496  s 
14497 ---
14498  1
14499  2
14500  3
14501  4
14502 (4 rows)
14503
14504 -- presenting an array, the subscript and the subscripted
14505 -- value requires a subquery
14506 SELECT * FROM arrays;
14507          a          
14508 --------------------
14509  {-1,-2}
14510  {100,200,300}
14511 (2 rows)
14512
14513 SELECT a AS array, s AS subscript, a[s] AS value
14514 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
14515      array     | subscript | value
14516 ---------------+-----------+-------
14517  {-1,-2}       |         1 |    -1
14518  {-1,-2}       |         2 |    -2
14519  {100,200,300} |         1 |   100
14520  {100,200,300} |         2 |   200
14521  {100,200,300} |         3 |   300
14522 (5 rows)
14523
14524 -- unnest a 2D array
14525 CREATE OR REPLACE FUNCTION unnest2(anyarray)
14526 RETURNS SETOF anyelement AS $$
14527 select $1[i][j]
14528    from generate_subscripts($1,1) g1(i),
14529         generate_subscripts($1,2) g2(j);
14530 $$ LANGUAGE sql IMMUTABLE;
14531 CREATE FUNCTION
14532 SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
14533  unnest2 
14534 ---------
14535        1
14536        2
14537        3
14538        4
14539 (4 rows)
14540 </programlisting>
14541   </para>
14542
14543   <indexterm>
14544    <primary>ordinality</primary>
14545   </indexterm>
14546
14547   <para>
14548    When a function in the <literal>FROM</literal> clause is suffixed
14549    by <literal>WITH ORDINALITY</literal>, a <type>bigint</type> column is
14550    appended to the output which starts from 1 and increments by 1 for each row
14551    of the function's output.  This is most useful in the case of set returning
14552    functions such as <function>unnest()</>.
14553
14554 <programlisting>
14555 -- set returning function WITH ORDINALITY
14556 SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
14557        ls        | n
14558 -----------------+----
14559  pg_serial       |  1
14560  pg_twophase     |  2
14561  postmaster.opts |  3
14562  pg_notify       |  4
14563  postgresql.conf |  5
14564  pg_tblspc       |  6
14565  logfile         |  7
14566  base            |  8
14567  postmaster.pid  |  9
14568  pg_ident.conf   | 10
14569  global          | 11
14570  pg_clog         | 12
14571  pg_snapshots    | 13
14572  pg_multixact    | 14
14573  PG_VERSION      | 15
14574  pg_xlog         | 16
14575  pg_hba.conf     | 17
14576  pg_stat_tmp     | 18
14577  pg_subtrans     | 19
14578 (19 rows)
14579 </programlisting>
14580   </para>
14581
14582  </sect1>
14583
14584  <sect1 id="functions-info">
14585   <title>System Information Functions</title>
14586
14587   <para>
14588    <xref linkend="functions-info-session-table"> shows several
14589    functions that extract session and system information.
14590   </para>
14591
14592   <para>
14593    In addition to the functions listed in this section, there are a number of
14594    functions related to the statistics system that also provide system
14595    information. See <xref linkend="monitoring-stats-views"> for more
14596    information.
14597   </para>
14598
14599    <table id="functions-info-session-table">
14600     <title>Session Information Functions</title>
14601     <tgroup cols="3">
14602      <thead>
14603       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14604      </thead>
14605
14606      <tbody>
14607       <row>
14608        <entry><literal><function>current_catalog</function></literal></entry>
14609        <entry><type>name</type></entry>
14610        <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
14611       </row>
14612
14613       <row>
14614        <entry><literal><function>current_database()</function></literal></entry>
14615        <entry><type>name</type></entry>
14616        <entry>name of current database</entry>
14617       </row>
14618
14619       <row>
14620        <entry><literal><function>current_query()</function></literal></entry>
14621        <entry><type>text</type></entry>
14622        <entry>text of the currently executing query, as submitted
14623        by the client (might contain more than one statement)</entry>
14624       </row>
14625
14626       <row>
14627        <entry><literal><function>current_schema</function>[()]</literal></entry>
14628        <entry><type>name</type></entry>
14629        <entry>name of current schema</entry>
14630       </row>
14631
14632       <row>
14633        <entry><literal><function>current_schemas(<type>boolean</type>)</function></literal></entry>
14634        <entry><type>name[]</type></entry>
14635        <entry>names of schemas in search path, optionally including implicit schemas</entry>
14636       </row>
14637
14638       <row>
14639        <entry><literal><function>current_user</function></literal></entry>
14640        <entry><type>name</type></entry>
14641        <entry>user name of current execution context</entry>
14642       </row>
14643
14644       <row>
14645        <entry><literal><function>inet_client_addr()</function></literal></entry>
14646        <entry><type>inet</type></entry>
14647        <entry>address of the remote connection</entry>
14648       </row>
14649
14650       <row>
14651        <entry><literal><function>inet_client_port()</function></literal></entry>
14652        <entry><type>int</type></entry>
14653        <entry>port of the remote connection</entry>
14654       </row>
14655
14656       <row>
14657        <entry><literal><function>inet_server_addr()</function></literal></entry>
14658        <entry><type>inet</type></entry>
14659        <entry>address of the local connection</entry>
14660       </row>
14661
14662       <row>
14663        <entry><literal><function>inet_server_port()</function></literal></entry>
14664        <entry><type>int</type></entry>
14665        <entry>port of the local connection</entry>
14666       </row>
14667
14668       <row>
14669        <!-- See also the entry for this in monitoring.sgml -->
14670        <entry><literal><function>pg_backend_pid()</function></literal></entry>
14671        <entry><type>int</type></entry>
14672        <entry>
14673         Process ID of the server process attached to the current session
14674        </entry>
14675       </row>
14676
14677       <row>
14678        <entry><literal><function>pg_conf_load_time()</function></literal></entry>
14679        <entry><type>timestamp with time zone</type></entry>
14680        <entry>configuration load time</entry>
14681       </row>
14682
14683       <row>
14684        <entry><literal><function>pg_is_other_temp_schema(<type>oid</type>)</function></literal></entry>
14685        <entry><type>boolean</type></entry>
14686        <entry>is schema another session's temporary schema?</entry>
14687       </row>
14688
14689       <row>
14690        <entry><literal><function>pg_listening_channels()</function></literal></entry>
14691        <entry><type>setof text</type></entry>
14692        <entry>channel names that the session is currently listening on</entry>
14693       </row>
14694
14695       <row>
14696        <entry><literal><function>pg_my_temp_schema()</function></literal></entry>
14697        <entry><type>oid</type></entry>
14698        <entry>OID of session's temporary schema, or 0 if none</entry>
14699       </row>
14700
14701       <row>
14702        <entry><literal><function>pg_postmaster_start_time()</function></literal></entry>
14703        <entry><type>timestamp with time zone</type></entry>
14704        <entry>server start time</entry>
14705       </row>
14706
14707       <row>
14708        <entry><literal><function>pg_trigger_depth()</function></literal></entry>
14709        <entry><type>int</type></entry>
14710        <entry>current nesting level of <productname>PostgreSQL</> triggers
14711        (0 if not called, directly or indirectly, from inside a trigger)</entry>
14712       </row>
14713
14714       <row>
14715        <entry><literal><function>session_user</function></literal></entry>
14716        <entry><type>name</type></entry>
14717        <entry>session user name</entry>
14718       </row>
14719
14720       <row>
14721        <entry><literal><function>user</function></literal></entry>
14722        <entry><type>name</type></entry>
14723        <entry>equivalent to <function>current_user</function></entry>
14724       </row>
14725
14726       <row>
14727        <entry><literal><function>version()</function></literal></entry>
14728        <entry><type>text</type></entry>
14729        <entry><productname>PostgreSQL</> version information. See also <xref linkend="guc-server-version-num"> for a machine-readable version.</entry>
14730       </row>
14731      </tbody>
14732     </tgroup>
14733    </table>
14734
14735    <note>
14736     <para>
14737      <function>current_catalog</function>, <function>current_schema</function>,
14738      <function>current_user</function>, <function>session_user</function>,
14739      and <function>user</function> have special syntactic status
14740      in <acronym>SQL</acronym>: they must be called without trailing
14741      parentheses.  (In PostgreSQL, parentheses can optionally be used with
14742      <function>current_schema</function>, but not with the others.)
14743     </para>
14744    </note>
14745
14746    <indexterm>
14747     <primary>current_catalog</primary>
14748    </indexterm>
14749
14750    <indexterm>
14751     <primary>current_database</primary>
14752    </indexterm>
14753
14754    <indexterm>
14755     <primary>current_query</primary>
14756    </indexterm>
14757
14758    <indexterm>
14759     <primary>current_schema</primary>
14760    </indexterm>
14761
14762    <indexterm>
14763     <primary>current_schemas</primary>
14764    </indexterm>
14765
14766    <indexterm>
14767     <primary>current_user</primary>
14768    </indexterm>
14769
14770    <indexterm>
14771     <primary>pg_backend_pid</primary>
14772    </indexterm>
14773
14774    <indexterm>
14775     <primary>schema</primary>
14776     <secondary>current</secondary>
14777    </indexterm>
14778
14779    <indexterm>
14780     <primary>search path</primary>
14781     <secondary>current</secondary>
14782    </indexterm>
14783
14784    <indexterm>
14785     <primary>session_user</primary>
14786    </indexterm>
14787
14788    <indexterm>
14789     <primary>user</primary>
14790     <secondary>current</secondary>
14791    </indexterm>
14792
14793    <indexterm>
14794     <primary>user</primary>
14795    </indexterm>
14796
14797    <para>
14798     The <function>session_user</function> is normally the user who initiated
14799     the current database connection; but superusers can change this setting
14800     with <xref linkend="sql-set-session-authorization">.
14801     The <function>current_user</function> is the user identifier
14802     that is applicable for permission checking. Normally it is equal
14803     to the session user, but it can be changed with
14804     <xref linkend="sql-set-role">.
14805     It also changes during the execution of
14806     functions with the attribute <literal>SECURITY DEFINER</literal>.
14807     In Unix parlance, the session user is the <quote>real user</quote> and
14808     the current user is the <quote>effective user</quote>.
14809    </para>
14810
14811    <para>
14812     <function>current_schema</function> returns the name of the schema that is
14813     first in the search path (or a null value if the search path is
14814     empty).  This is the schema that will be used for any tables or
14815     other named objects that are created without specifying a target schema.
14816     <function>current_schemas(boolean)</function> returns an array of the names of all
14817     schemas presently in the search path.  The Boolean option determines whether or not
14818     implicitly included system schemas such as <literal>pg_catalog</> are included in the
14819     returned search path.
14820    </para>
14821
14822    <note>
14823     <para>
14824      The search path can be altered at run time.  The command is:
14825 <programlisting>
14826 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
14827 </programlisting>
14828     </para>
14829    </note>
14830
14831    <indexterm>
14832     <primary>pg_listening_channels</primary>
14833    </indexterm>
14834
14835    <para>
14836     <function>pg_listening_channels</function> returns a set of names of
14837     channels that the current session is listening to.  See <xref
14838     linkend="sql-listen"> for more information.
14839    </para>
14840
14841    <indexterm>
14842     <primary>inet_client_addr</primary>
14843    </indexterm>
14844
14845    <indexterm>
14846     <primary>inet_client_port</primary>
14847    </indexterm>
14848
14849    <indexterm>
14850     <primary>inet_server_addr</primary>
14851    </indexterm>
14852
14853    <indexterm>
14854     <primary>inet_server_port</primary>
14855    </indexterm>
14856
14857    <para>
14858      <function>inet_client_addr</function> returns the IP address of the
14859      current client, and <function>inet_client_port</function> returns the
14860      port number.
14861      <function>inet_server_addr</function> returns the IP address on which
14862      the server accepted the current connection, and
14863      <function>inet_server_port</function> returns the port number.
14864      All these functions return NULL if the current connection is via a
14865      Unix-domain socket.
14866    </para>
14867
14868    <indexterm>
14869     <primary>pg_my_temp_schema</primary>
14870    </indexterm>
14871
14872    <indexterm>
14873     <primary>pg_is_other_temp_schema</primary>
14874    </indexterm>
14875
14876    <para>
14877     <function>pg_my_temp_schema</function> returns the OID of the current
14878     session's temporary schema, or zero if it has none (because it has not
14879     created any temporary tables).
14880     <function>pg_is_other_temp_schema</function> returns true if the
14881     given OID is the OID of another session's temporary schema.
14882     (This can be useful, for example, to exclude other sessions' temporary
14883     tables from a catalog display.)
14884    </para>
14885
14886    <indexterm>
14887     <primary>pg_postmaster_start_time</primary>
14888    </indexterm>
14889
14890    <para>
14891     <function>pg_postmaster_start_time</function> returns the
14892     <type>timestamp with time zone</type> when the
14893     server started.
14894    </para>
14895
14896    <indexterm>
14897     <primary>pg_conf_load_time</primary>
14898    </indexterm>
14899
14900    <para>
14901     <function>pg_conf_load_time</function> returns the
14902     <type>timestamp with time zone</type> when the
14903     server configuration files were last loaded.
14904     (If the current session was alive at the time, this will be the time
14905     when the session itself re-read the configuration files, so the
14906     reading will vary a little in different sessions.  Otherwise it is
14907     the time when the postmaster process re-read the configuration files.)
14908    </para>
14909
14910    <indexterm>
14911     <primary>version</primary>
14912    </indexterm>
14913
14914    <para>
14915     <function>version</function> returns a string describing the
14916     <productname>PostgreSQL</productname> server's version. You can also
14917     get this information from <xref linkend="guc-server-version"> or
14918     for a machine-readable version, <xref linkend="guc-server-version-num">.
14919     Software developers should use <literal>server_version_num</literal>
14920     (available since 8.2) or <xref linkend="libpq-pqserverversion"> instead
14921     of parsing the text version.
14922    </para>
14923
14924   <indexterm>
14925    <primary>privilege</primary>
14926    <secondary>querying</secondary>
14927   </indexterm>
14928
14929   <para>
14930    <xref linkend="functions-info-access-table"> lists functions that
14931    allow the user to query object access privileges programmatically.
14932    See <xref linkend="ddl-priv"> for more information about
14933    privileges.
14934   </para>
14935
14936    <table id="functions-info-access-table">
14937     <title>Access Privilege Inquiry Functions</title>
14938     <tgroup cols="3">
14939      <thead>
14940       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14941      </thead>
14942
14943      <tbody>
14944       <row>
14945        <entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
14946                                   <parameter>table</parameter>,
14947                                   <parameter>privilege</parameter>)</literal>
14948        </entry>
14949        <entry><type>boolean</type></entry>
14950        <entry>does user have privilege for any column of table</entry>
14951       </row>
14952       <row>
14953        <entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
14954                                   <parameter>privilege</parameter>)</literal>
14955        </entry>
14956        <entry><type>boolean</type></entry>
14957        <entry>does current user have privilege for any column of table</entry>
14958       </row>
14959       <row>
14960        <entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
14961                                   <parameter>table</parameter>,
14962                                   <parameter>column</parameter>,
14963                                   <parameter>privilege</parameter>)</literal>
14964        </entry>
14965        <entry><type>boolean</type></entry>
14966        <entry>does user have privilege for column</entry>
14967       </row>
14968       <row>
14969        <entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
14970                                   <parameter>column</parameter>,
14971                                   <parameter>privilege</parameter>)</literal>
14972        </entry>
14973        <entry><type>boolean</type></entry>
14974        <entry>does current user have privilege for column</entry>
14975       </row>
14976       <row>
14977        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
14978                                   <parameter>database</parameter>,
14979                                   <parameter>privilege</parameter>)</literal>
14980        </entry>
14981        <entry><type>boolean</type></entry>
14982        <entry>does user have privilege for database</entry>
14983       </row>
14984       <row>
14985        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
14986                                   <parameter>privilege</parameter>)</literal>
14987        </entry>
14988        <entry><type>boolean</type></entry>
14989        <entry>does current user have privilege for database</entry>
14990       </row>
14991       <row>
14992        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
14993                                   <parameter>fdw</parameter>,
14994                                   <parameter>privilege</parameter>)</literal>
14995        </entry>
14996        <entry><type>boolean</type></entry>
14997        <entry>does user have privilege for foreign-data wrapper</entry>
14998       </row>
14999       <row>
15000        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
15001                                   <parameter>privilege</parameter>)</literal>
15002        </entry>
15003        <entry><type>boolean</type></entry>
15004        <entry>does current user have privilege for foreign-data wrapper</entry>
15005       </row>
15006       <row>
15007        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
15008                                   <parameter>function</parameter>,
15009                                   <parameter>privilege</parameter>)</literal>
15010        </entry>
15011        <entry><type>boolean</type></entry>
15012        <entry>does user have privilege for function</entry>
15013       </row>
15014       <row>
15015        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
15016                                   <parameter>privilege</parameter>)</literal>
15017        </entry>
15018        <entry><type>boolean</type></entry>
15019        <entry>does current user have privilege for function</entry>
15020       </row>
15021       <row>
15022        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
15023                                   <parameter>language</parameter>,
15024                                   <parameter>privilege</parameter>)</literal>
15025        </entry>
15026        <entry><type>boolean</type></entry>
15027        <entry>does user have privilege for language</entry>
15028       </row>
15029       <row>
15030        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
15031                                   <parameter>privilege</parameter>)</literal>
15032        </entry>
15033        <entry><type>boolean</type></entry>
15034        <entry>does current user have privilege for language</entry>
15035       </row>
15036       <row>
15037        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
15038                                   <parameter>schema</parameter>,
15039                                   <parameter>privilege</parameter>)</literal>
15040        </entry>
15041        <entry><type>boolean</type></entry>
15042        <entry>does user have privilege for schema</entry>
15043       </row>
15044       <row>
15045        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
15046                                   <parameter>privilege</parameter>)</literal>
15047        </entry>
15048        <entry><type>boolean</type></entry>
15049        <entry>does current user have privilege for schema</entry>
15050       </row>
15051       <row>
15052        <entry><literal><function>has_sequence_privilege</function>(<parameter>user</parameter>,
15053                                   <parameter>sequence</parameter>,
15054                                   <parameter>privilege</parameter>)</literal>
15055        </entry>
15056        <entry><type>boolean</type></entry>
15057        <entry>does user have privilege for sequence</entry>
15058       </row>
15059       <row>
15060        <entry><literal><function>has_sequence_privilege</function>(<parameter>sequence</parameter>,
15061                                   <parameter>privilege</parameter>)</literal>
15062        </entry>
15063        <entry><type>boolean</type></entry>
15064        <entry>does current user have privilege for sequence</entry>
15065       </row>
15066       <row>
15067        <entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
15068                                   <parameter>server</parameter>,
15069                                   <parameter>privilege</parameter>)</literal>
15070        </entry>
15071        <entry><type>boolean</type></entry>
15072        <entry>does user have privilege for foreign server</entry>
15073       </row>
15074       <row>
15075        <entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
15076                                   <parameter>privilege</parameter>)</literal>
15077        </entry>
15078        <entry><type>boolean</type></entry>
15079        <entry>does current user have privilege for foreign server</entry>
15080       </row>
15081       <row>
15082        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
15083                                   <parameter>table</parameter>,
15084                                   <parameter>privilege</parameter>)</literal>
15085        </entry>
15086        <entry><type>boolean</type></entry>
15087        <entry>does user have privilege for table</entry>
15088       </row>
15089       <row>
15090        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
15091                                   <parameter>privilege</parameter>)</literal>
15092        </entry>
15093        <entry><type>boolean</type></entry>
15094        <entry>does current user have privilege for table</entry>
15095       </row>
15096       <row>
15097        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
15098                                   <parameter>tablespace</parameter>,
15099                                   <parameter>privilege</parameter>)</literal>
15100        </entry>
15101        <entry><type>boolean</type></entry>
15102        <entry>does user have privilege for tablespace</entry>
15103       </row>
15104       <row>
15105        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
15106                                   <parameter>privilege</parameter>)</literal>
15107        </entry>
15108        <entry><type>boolean</type></entry>
15109        <entry>does current user have privilege for tablespace</entry>
15110       </row>
15111       <row>
15112        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
15113                                   <parameter>role</parameter>,
15114                                   <parameter>privilege</parameter>)</literal>
15115        </entry>
15116        <entry><type>boolean</type></entry>
15117        <entry>does user have privilege for role</entry>
15118       </row>
15119       <row>
15120        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
15121                                   <parameter>privilege</parameter>)</literal>
15122        </entry>
15123        <entry><type>boolean</type></entry>
15124        <entry>does current user have privilege for role</entry>
15125       </row>
15126      </tbody>
15127     </tgroup>
15128    </table>
15129
15130    <indexterm>
15131     <primary>has_any_column_privilege</primary>
15132    </indexterm>
15133    <indexterm>
15134     <primary>has_column_privilege</primary>
15135    </indexterm>
15136    <indexterm>
15137     <primary>has_database_privilege</primary>
15138    </indexterm>
15139    <indexterm>
15140     <primary>has_function_privilege</primary>
15141    </indexterm>
15142    <indexterm>
15143     <primary>has_foreign_data_wrapper_privilege</primary>
15144    </indexterm>
15145    <indexterm>
15146     <primary>has_language_privilege</primary>
15147    </indexterm>
15148    <indexterm>
15149     <primary>has_schema_privilege</primary>
15150    </indexterm>
15151    <indexterm>
15152     <primary>has_server_privilege</primary>
15153    </indexterm>
15154    <indexterm>
15155     <primary>has_sequence_privilege</primary>
15156    </indexterm>
15157    <indexterm>
15158     <primary>has_table_privilege</primary>
15159    </indexterm>
15160    <indexterm>
15161     <primary>has_tablespace_privilege</primary>
15162    </indexterm>
15163    <indexterm>
15164     <primary>pg_has_role</primary>
15165    </indexterm>
15166
15167    <para>
15168     <function>has_table_privilege</function> checks whether a user
15169     can access a table in a particular way.  The user can be
15170     specified by name, by OID (<literal>pg_authid.oid</literal>),
15171     <literal>public</> to indicate the PUBLIC pseudo-role, or if the argument is
15172     omitted
15173     <function>current_user</function> is assumed.  The table can be specified
15174     by name or by OID.  (Thus, there are actually six variants of
15175     <function>has_table_privilege</function>, which can be distinguished by
15176     the number and types of their arguments.)  When specifying by name,
15177     the name can be schema-qualified if necessary.
15178     The desired access privilege type
15179     is specified by a text string, which must evaluate to one of the
15180     values <literal>SELECT</literal>, <literal>INSERT</literal>,
15181     <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
15182     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.  Optionally,
15183     <literal>WITH GRANT OPTION</> can be added to a privilege type to test
15184     whether the privilege is held with grant option.  Also, multiple privilege
15185     types can be listed separated by commas, in which case the result will
15186     be <literal>true</> if any of the listed privileges is held.
15187     (Case of the privilege string is not significant, and extra whitespace
15188     is allowed between but not within privilege names.)
15189     Some examples:
15190 <programlisting>
15191 SELECT has_table_privilege('myschema.mytable', 'select');
15192 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
15193 </programlisting>
15194    </para>
15195
15196    <para>
15197     <function>has_sequence_privilege</function> checks whether a user
15198     can access a sequence in a particular way.  The possibilities for its
15199     arguments are analogous to <function>has_table_privilege</function>.
15200     The desired access privilege type must evaluate to one of
15201     <literal>USAGE</literal>,
15202     <literal>SELECT</literal>, or
15203     <literal>UPDATE</literal>.
15204    </para>
15205
15206    <para>
15207     <function>has_any_column_privilege</function> checks whether a user can
15208     access any column of a table in a particular way.
15209     Its argument possibilities
15210     are analogous to <function>has_table_privilege</>,
15211     except that the desired access privilege type must evaluate to some
15212     combination of
15213     <literal>SELECT</literal>,
15214     <literal>INSERT</literal>,
15215     <literal>UPDATE</literal>, or
15216     <literal>REFERENCES</literal>.  Note that having any of these privileges
15217     at the table level implicitly grants it for each column of the table,
15218     so <function>has_any_column_privilege</function> will always return
15219     <literal>true</> if <function>has_table_privilege</> does for the same
15220     arguments.  But <function>has_any_column_privilege</> also succeeds if
15221     there is a column-level grant of the privilege for at least one column.
15222    </para>
15223
15224    <para>
15225     <function>has_column_privilege</function> checks whether a user
15226     can access a column in a particular way.
15227     Its argument possibilities
15228     are analogous to <function>has_table_privilege</function>,
15229     with the addition that the column can be specified either by name
15230     or attribute number.
15231     The desired access privilege type must evaluate to some combination of
15232     <literal>SELECT</literal>,
15233     <literal>INSERT</literal>,
15234     <literal>UPDATE</literal>, or
15235     <literal>REFERENCES</literal>.  Note that having any of these privileges
15236     at the table level implicitly grants it for each column of the table.
15237    </para>
15238
15239    <para>
15240     <function>has_database_privilege</function> checks whether a user
15241     can access a database in a particular way.
15242     Its argument possibilities
15243     are analogous to <function>has_table_privilege</function>.
15244     The desired access privilege type must evaluate to some combination of
15245     <literal>CREATE</literal>,
15246     <literal>CONNECT</literal>,
15247     <literal>TEMPORARY</literal>, or
15248     <literal>TEMP</literal> (which is equivalent to
15249     <literal>TEMPORARY</literal>).
15250    </para>
15251
15252    <para>
15253     <function>has_function_privilege</function> checks whether a user
15254     can access a function in a particular way.
15255     Its argument possibilities
15256     are analogous to <function>has_table_privilege</function>.
15257     When specifying a function by a text string rather than by OID,
15258     the allowed input is the same as for the <type>regprocedure</> data type
15259     (see <xref linkend="datatype-oid">).
15260     The desired access privilege type must evaluate to
15261     <literal>EXECUTE</literal>.
15262     An example is:
15263 <programlisting>
15264 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
15265 </programlisting>
15266    </para>
15267
15268    <para>
15269     <function>has_foreign_data_wrapper_privilege</function> checks whether a user
15270     can access a foreign-data wrapper in a particular way.
15271     Its argument possibilities
15272     are analogous to <function>has_table_privilege</function>.
15273     The desired access privilege type must evaluate to
15274     <literal>USAGE</literal>.
15275    </para>
15276
15277    <para>
15278     <function>has_language_privilege</function> checks whether a user
15279     can access a procedural language in a particular way.
15280     Its argument possibilities
15281     are analogous to <function>has_table_privilege</function>.
15282     The desired access privilege type must evaluate to
15283     <literal>USAGE</literal>.
15284    </para>
15285
15286    <para>
15287     <function>has_schema_privilege</function> checks whether a user
15288     can access a schema in a particular way.
15289     Its argument possibilities
15290     are analogous to <function>has_table_privilege</function>.
15291     The desired access privilege type must evaluate to some combination of
15292     <literal>CREATE</literal> or
15293     <literal>USAGE</literal>.
15294    </para>
15295
15296    <para>
15297     <function>has_server_privilege</function> checks whether a user
15298     can access a foreign server in a particular way.
15299     Its argument possibilities
15300     are analogous to <function>has_table_privilege</function>.
15301     The desired access privilege type must evaluate to
15302     <literal>USAGE</literal>.
15303    </para>
15304
15305    <para>
15306     <function>has_tablespace_privilege</function> checks whether a user
15307     can access a tablespace in a particular way.
15308     Its argument possibilities
15309     are analogous to <function>has_table_privilege</function>.
15310     The desired access privilege type must evaluate to
15311     <literal>CREATE</literal>.
15312    </para>
15313
15314    <para>
15315     <function>pg_has_role</function> checks whether a user
15316     can access a role in a particular way.
15317     Its argument possibilities
15318     are analogous to <function>has_table_privilege</function>,
15319     except that <literal>public</> is not allowed as a user name.
15320     The desired access privilege type must evaluate to some combination of
15321     <literal>MEMBER</literal> or
15322     <literal>USAGE</literal>.
15323     <literal>MEMBER</literal> denotes direct or indirect membership in
15324     the role (that is, the right to do <command>SET ROLE</>), while
15325     <literal>USAGE</literal> denotes whether the privileges of the role
15326     are immediately available without doing <command>SET ROLE</>.
15327    </para>
15328
15329   <para>
15330    <xref linkend="functions-info-schema-table"> shows functions that
15331    determine whether a certain object is <firstterm>visible</> in the
15332    current schema search path.
15333    For example, a table is said to be visible if its
15334    containing schema is in the search path and no table of the same
15335    name appears earlier in the search path.  This is equivalent to the
15336    statement that the table can be referenced by name without explicit
15337    schema qualification.  To list the names of all visible tables:
15338 <programlisting>
15339 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
15340 </programlisting>
15341   </para>
15342
15343    <indexterm>
15344     <primary>search path</primary>
15345     <secondary>object visibility</secondary>
15346    </indexterm>
15347
15348    <table id="functions-info-schema-table">
15349     <title>Schema Visibility Inquiry Functions</title>
15350     <tgroup cols="3">
15351      <thead>
15352       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
15353      </thead>
15354
15355      <tbody>
15356       <row>
15357        <entry><literal><function>pg_collation_is_visible(<parameter>collation_oid</parameter>)</function></literal>
15358        </entry>
15359        <entry><type>boolean</type></entry>
15360        <entry>is collation visible in search path</entry>
15361       </row>
15362       <row>
15363        <entry><literal><function>pg_conversion_is_visible(<parameter>conversion_oid</parameter>)</function></literal>
15364        </entry>
15365        <entry><type>boolean</type></entry>
15366        <entry>is conversion visible in search path</entry>
15367       </row>
15368       <row>
15369        <entry><literal><function>pg_function_is_visible(<parameter>function_oid</parameter>)</function></literal>
15370        </entry>
15371        <entry><type>boolean</type></entry>
15372        <entry>is function visible in search path</entry>
15373       </row>
15374       <row>
15375        <entry><literal><function>pg_opclass_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
15376        </entry>
15377        <entry><type>boolean</type></entry>
15378        <entry>is operator class visible in search path</entry>
15379       </row>
15380       <row>
15381        <entry><literal><function>pg_operator_is_visible(<parameter>operator_oid</parameter>)</function></literal>
15382        </entry>
15383        <entry><type>boolean</type></entry>
15384        <entry>is operator visible in search path</entry>
15385       </row>
15386       <row>
15387        <entry><literal><function>pg_opfamily_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
15388        </entry>
15389        <entry><type>boolean</type></entry>
15390        <entry>is operator family visible in search path</entry>
15391       </row>
15392       <row>
15393        <entry><literal><function>pg_table_is_visible(<parameter>table_oid</parameter>)</function></literal>
15394        </entry>
15395        <entry><type>boolean</type></entry>
15396        <entry>is table visible in search path</entry>
15397       </row>
15398       <row>
15399        <entry><literal><function>pg_ts_config_is_visible(<parameter>config_oid</parameter>)</function></literal>
15400        </entry>
15401        <entry><type>boolean</type></entry>
15402        <entry>is text search configuration visible in search path</entry>
15403       </row>
15404       <row>
15405        <entry><literal><function>pg_ts_dict_is_visible(<parameter>dict_oid</parameter>)</function></literal>
15406        </entry>
15407        <entry><type>boolean</type></entry>
15408        <entry>is text search dictionary visible in search path</entry>
15409       </row>
15410       <row>
15411        <entry><literal><function>pg_ts_parser_is_visible(<parameter>parser_oid</parameter>)</function></literal>
15412        </entry>
15413        <entry><type>boolean</type></entry>
15414        <entry>is text search parser visible in search path</entry>
15415       </row>
15416       <row>
15417        <entry><literal><function>pg_ts_template_is_visible(<parameter>template_oid</parameter>)</function></literal>
15418        </entry>
15419        <entry><type>boolean</type></entry>
15420        <entry>is text search template visible in search path</entry>
15421       </row>
15422       <row>
15423        <entry><literal><function>pg_type_is_visible(<parameter>type_oid</parameter>)</function></literal>
15424        </entry>
15425        <entry><type>boolean</type></entry>
15426        <entry>is type (or domain) visible in search path</entry>
15427       </row>
15428      </tbody>
15429     </tgroup>
15430    </table>
15431
15432    <indexterm>
15433     <primary>pg_collation_is_visible</primary>
15434    </indexterm>
15435    <indexterm>
15436     <primary>pg_conversion_is_visible</primary>
15437    </indexterm>
15438    <indexterm>
15439     <primary>pg_function_is_visible</primary>
15440    </indexterm>
15441    <indexterm>
15442     <primary>pg_opclass_is_visible</primary>
15443    </indexterm>
15444    <indexterm>
15445     <primary>pg_operator_is_visible</primary>
15446    </indexterm>
15447    <indexterm>
15448     <primary>pg_opfamily_is_visible</primary>
15449    </indexterm>
15450    <indexterm>
15451     <primary>pg_table_is_visible</primary>
15452    </indexterm>
15453    <indexterm>
15454     <primary>pg_ts_config_is_visible</primary>
15455    </indexterm>
15456    <indexterm>
15457     <primary>pg_ts_dict_is_visible</primary>
15458    </indexterm>
15459    <indexterm>
15460     <primary>pg_ts_parser_is_visible</primary>
15461    </indexterm>
15462    <indexterm>
15463     <primary>pg_ts_template_is_visible</primary>
15464    </indexterm>
15465    <indexterm>
15466     <primary>pg_type_is_visible</primary>
15467    </indexterm>
15468
15469    <para>
15470     Each function performs the visibility check for one type of database
15471     object.  Note that <function>pg_table_is_visible</function> can also be used
15472     with views, indexes and sequences; <function>pg_type_is_visible</function>
15473     can also be used with domains. For functions and operators, an object in
15474     the search path is visible if there is no object of the same name
15475     <emphasis>and argument data type(s)</> earlier in the path.  For operator
15476     classes, both name and associated index access method are considered.
15477    </para>
15478
15479    <para>
15480     All these functions require object OIDs to identify the object to be
15481     checked.  If you want to test an object by name, it is convenient to use
15482     the OID alias types (<type>regclass</>, <type>regtype</>,
15483     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
15484     or <type>regdictionary</>),
15485     for example:
15486 <programlisting>
15487 SELECT pg_type_is_visible('myschema.widget'::regtype);
15488 </programlisting>
15489     Note that it would not make much sense to test a non-schema-qualified
15490     type name in this way &mdash; if the name can be recognized at all, it must be visible.
15491    </para>
15492
15493    <indexterm>
15494     <primary>format_type</primary>
15495    </indexterm>
15496
15497    <indexterm>
15498     <primary>pg_get_constraintdef</primary>
15499    </indexterm>
15500
15501    <indexterm>
15502     <primary>pg_get_expr</primary>
15503    </indexterm>
15504
15505    <indexterm>
15506     <primary>pg_get_functiondef</primary>
15507    </indexterm>
15508
15509    <indexterm>
15510     <primary>pg_get_function_arguments</primary>
15511    </indexterm>
15512
15513    <indexterm>
15514     <primary>pg_get_function_identity_arguments</primary>
15515    </indexterm>
15516
15517    <indexterm>
15518     <primary>pg_get_function_result</primary>
15519    </indexterm>
15520
15521    <indexterm>
15522     <primary>pg_get_indexdef</primary>
15523    </indexterm>
15524
15525    <indexterm>
15526     <primary>pg_get_keywords</primary>
15527    </indexterm>
15528
15529    <indexterm>
15530     <primary>pg_get_ruledef</primary>
15531    </indexterm>
15532
15533    <indexterm>
15534     <primary>pg_get_serial_sequence</primary>
15535    </indexterm>
15536
15537    <indexterm>
15538     <primary>pg_get_triggerdef</primary>
15539    </indexterm>
15540
15541    <indexterm>
15542     <primary>pg_get_userbyid</primary>
15543    </indexterm>
15544
15545    <indexterm>
15546     <primary>pg_get_viewdef</primary>
15547    </indexterm>
15548
15549    <indexterm>
15550     <primary>pg_options_to_table</primary>
15551    </indexterm>
15552
15553    <indexterm>
15554     <primary>pg_tablespace_databases</primary>
15555    </indexterm>
15556
15557    <indexterm>
15558     <primary>pg_tablespace_location</primary>
15559    </indexterm>
15560
15561    <indexterm>
15562     <primary>pg_typeof</primary>
15563    </indexterm>
15564
15565    <indexterm>
15566     <primary>collation for</primary>
15567    </indexterm>
15568
15569    <indexterm>
15570     <primary>to_regclass</primary>
15571    </indexterm>
15572
15573    <indexterm>
15574     <primary>to_regproc</primary>
15575    </indexterm>
15576
15577    <indexterm>
15578     <primary>to_regprocedure</primary>
15579    </indexterm>
15580
15581    <indexterm>
15582     <primary>to_regoper</primary>
15583    </indexterm>
15584
15585    <indexterm>
15586     <primary>to_regoperator</primary>
15587    </indexterm>
15588
15589    <indexterm>
15590     <primary>to_regtype</primary>
15591    </indexterm>
15592
15593   <para>
15594    <xref linkend="functions-info-catalog-table"> lists functions that
15595    extract information from the system catalogs.
15596   </para>
15597
15598    <table id="functions-info-catalog-table">
15599     <title>System Catalog Information Functions</title>
15600     <tgroup cols="3">
15601      <thead>
15602       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
15603      </thead>
15604
15605      <tbody>
15606       <row>
15607        <entry><literal><function>format_type(<parameter>type_oid</parameter>, <parameter>typemod</>)</function></literal></entry>
15608        <entry><type>text</type></entry>
15609        <entry>get SQL name of a data type</entry>
15610       </row>
15611       <row>
15612        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>)</function></literal></entry>
15613        <entry><type>text</type></entry>
15614        <entry>get definition of a constraint</entry>
15615       </row>
15616       <row>
15617        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
15618        <entry><type>text</type></entry>
15619        <entry>get definition of a constraint</entry>
15620       </row>
15621       <row>
15622        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>)</function></literal></entry>
15623        <entry><type>text</type></entry>
15624        <entry>decompile internal form of an expression, assuming that any Vars
15625        in it refer to the relation indicated by the second parameter</entry>
15626       </row>
15627       <row>
15628        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</function></literal></entry>
15629        <entry><type>text</type></entry>
15630        <entry>decompile internal form of an expression, assuming that any Vars
15631        in it refer to the relation indicated by the second parameter</entry>
15632       </row>
15633       <row>
15634        <entry><literal><function>pg_get_functiondef(<parameter>func_oid</parameter>)</function></literal></entry>
15635        <entry><type>text</type></entry>
15636        <entry>get definition of a function</entry>
15637       </row>
15638       <row>
15639        <entry><literal><function>pg_get_function_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
15640        <entry><type>text</type></entry>
15641        <entry>get argument list of function's definition (with default values)</entry>
15642       </row>
15643       <row>
15644        <entry><literal><function>pg_get_function_identity_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
15645        <entry><type>text</type></entry>
15646        <entry>get argument list to identify a function (without default values)</entry>
15647       </row>
15648       <row>
15649        <entry><literal><function>pg_get_function_result(<parameter>func_oid</parameter>)</function></literal></entry>
15650        <entry><type>text</type></entry>
15651        <entry>get <literal>RETURNS</> clause for function</entry>
15652       </row>
15653       <row>
15654        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>)</function></literal></entry>
15655        <entry><type>text</type></entry>
15656        <entry>get <command>CREATE INDEX</> command for index</entry>
15657       </row>
15658       <row>
15659        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</function></literal></entry>
15660        <entry><type>text</type></entry>
15661        <entry>get <command>CREATE INDEX</> command for index,
15662        or definition of just one index column when
15663        <parameter>column_no</> is not zero</entry>
15664       </row>
15665       <row>
15666        <entry><literal><function>pg_get_keywords()</function></literal></entry>
15667        <entry><type>setof record</type></entry>
15668        <entry>get list of SQL keywords and their categories</entry>
15669       </row>
15670       <row>
15671        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>)</function></literal></entry>
15672        <entry><type>text</type></entry>
15673        <entry>get <command>CREATE RULE</> command for rule</entry>
15674       </row>
15675       <row>
15676        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
15677        <entry><type>text</type></entry>
15678        <entry>get <command>CREATE RULE</> command for rule</entry>
15679       </row>
15680       <row>
15681        <entry><literal><function>pg_get_serial_sequence(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</function></literal></entry>
15682        <entry><type>text</type></entry>
15683        <entry>get name of the sequence that a <type>serial</type>, <type>smallserial</type> or <type>bigserial</type> column
15684        uses</entry>
15685       </row>
15686       <row>
15687        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
15688        <entry><type>text</type></entry>
15689        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
15690       </row>
15691       <row>
15692        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>, <parameter>pretty_bool</>)</entry>
15693        <entry><type>text</type></entry>
15694        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
15695       </row>
15696       <row>
15697        <entry><literal><function>pg_get_userbyid(<parameter>role_oid</parameter>)</function></literal></entry>
15698        <entry><type>name</type></entry>
15699        <entry>get role name with given OID</entry>
15700       </row>
15701       <row>
15702        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>)</function></literal></entry>
15703        <entry><type>text</type></entry>
15704        <entry>get underlying <command>SELECT</command> command for view or materialized view (<emphasis>deprecated</emphasis>)</entry>
15705       </row>
15706       <row>
15707        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
15708        <entry><type>text</type></entry>
15709        <entry>get underlying <command>SELECT</command> command for view or materialized view (<emphasis>deprecated</emphasis>)</entry>
15710       </row>
15711       <row>
15712        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>)</function></literal></entry>
15713        <entry><type>text</type></entry>
15714        <entry>get underlying <command>SELECT</command> command for view or materialized view</entry>
15715       </row>
15716       <row>
15717        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
15718        <entry><type>text</type></entry>
15719        <entry>get underlying <command>SELECT</command> command for view or materialized view</entry>
15720       </row>
15721       <row>
15722        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>wrap_column_int</>)</function></literal></entry>
15723        <entry><type>text</type></entry>
15724        <entry>get underlying <command>SELECT</command> command for view or
15725               materialized view; lines with fields are wrapped to specified
15726               number of columns, pretty-printing is implied</entry>
15727       </row>
15728       <row>
15729        <entry><literal><function>pg_options_to_table(<parameter>reloptions</parameter>)</function></literal></entry>
15730        <entry><type>setof record</type></entry>
15731        <entry>get the set of storage option name/value pairs</entry>
15732       </row>
15733       <row>
15734        <entry><literal><function>pg_tablespace_databases(<parameter>tablespace_oid</parameter>)</function></literal></entry>
15735        <entry><type>setof oid</type></entry>
15736        <entry>get the set of database OIDs that have objects in the tablespace</entry>
15737       </row>
15738       <row>
15739        <entry><literal><function>pg_tablespace_location(<parameter>tablespace_oid</parameter>)</function></literal></entry>
15740        <entry><type>text</type></entry>
15741        <entry>get the path in the file system that this tablespace is located in</entry>
15742       </row>
15743       <row>
15744        <entry><literal><function>pg_typeof(<parameter>any</parameter>)</function></literal></entry>
15745        <entry><type>regtype</type></entry>
15746        <entry>get the data type of any value</entry>
15747       </row>
15748       <row>
15749        <entry><literal><function>collation for (<parameter>any</parameter>)</function></literal></entry>
15750        <entry><type>text</type></entry>
15751        <entry>get the collation of the argument</entry>
15752       </row>
15753       <row>
15754        <entry><literal><function>to_regclass(<parameter>rel_name</parameter>)</function></literal></entry>
15755        <entry><type>regclass</type></entry>
15756        <entry>get the OID of the named relation</entry>
15757       </row>
15758       <row>
15759        <entry><literal><function>to_regproc(<parameter>func_name</parameter>)</function></literal></entry>
15760        <entry><type>regproc</type></entry>
15761        <entry>get the OID of the named function</entry>
15762       </row>
15763       <row>
15764        <entry><literal><function>to_regprocedure(<parameter>func_name</parameter>)</function></literal></entry>
15765        <entry><type>regprocedure</type></entry>
15766        <entry>get the OID of the named function</entry>
15767       </row>
15768       <row>
15769        <entry><literal><function>to_regoper(<parameter>operator_name</parameter>)</function></literal></entry>
15770        <entry><type>regoper</type></entry>
15771        <entry>get the OID of the named operator</entry>
15772       </row>
15773       <row>
15774        <entry><literal><function>to_regoperator(<parameter>operator_name</parameter>)</function></literal></entry>
15775        <entry><type>regoperator</type></entry>
15776        <entry>get the OID of the named operator</entry>
15777       </row>
15778       <row>
15779        <entry><literal><function>to_regtype(<parameter>type_name</parameter>)</function></literal></entry>
15780        <entry><type>regtype</type></entry>
15781        <entry>get the OID of the named type</entry>
15782       </row>
15783      </tbody>
15784     </tgroup>
15785    </table>
15786
15787   <para>
15788    <function>format_type</function> returns the SQL name of a data type that
15789    is identified by its type OID and possibly a type modifier.  Pass NULL
15790    for the type modifier if no specific modifier is known.
15791   </para>
15792
15793   <para>
15794    <function>pg_get_keywords</function> returns a set of records describing
15795    the SQL keywords recognized by the server. The <structfield>word</> column
15796    contains the keyword.  The <structfield>catcode</> column contains a
15797    category code: <literal>U</> for unreserved, <literal>C</> for column name,
15798    <literal>T</> for type or function name, or <literal>R</> for reserved.
15799    The <structfield>catdesc</> column contains a possibly-localized string
15800    describing the category.
15801   </para>
15802
15803   <para>
15804    <function>pg_get_constraintdef</function>,
15805    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
15806    and <function>pg_get_triggerdef</function>, respectively reconstruct the
15807    creating command for a constraint, index, rule, or trigger. (Note that this
15808    is a decompiled reconstruction, not the original text of the command.)
15809    <function>pg_get_expr</function> decompiles the internal form of an
15810    individual expression, such as the default value for a column.  It can be
15811    useful when examining the contents of system catalogs.  If the expression
15812    might contain Vars, specify the OID of the relation they refer to as the
15813    second parameter; if no Vars are expected, zero is sufficient.
15814    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
15815    query that defines a view. Most of these functions come in two variants,
15816    one of which can optionally <quote>pretty-print</> the result.  The
15817    pretty-printed format is more readable, but the default format is more
15818    likely to be interpreted the same way by future versions of
15819    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
15820    purposes.  Passing <literal>false</> for the pretty-print parameter yields
15821    the same result as the variant that does not have the parameter at all.
15822   </para>
15823
15824   <para>
15825    <function>pg_get_functiondef</> returns a complete
15826    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
15827    <function>pg_get_function_arguments</function> returns the argument list
15828    of a function, in the form it would need to appear in within
15829    <command>CREATE FUNCTION</>.
15830    <function>pg_get_function_result</function> similarly returns the
15831    appropriate <literal>RETURNS</> clause for the function.
15832    <function>pg_get_function_identity_arguments</function> returns the
15833    argument list necessary to identify a function, in the form it
15834    would need to appear in within <command>ALTER FUNCTION</>, for
15835    instance.  This form omits default values.
15836   </para>
15837
15838   <para>
15839    <function>pg_get_serial_sequence</function> returns the name of the
15840    sequence associated with a column, or NULL if no sequence is associated
15841    with the column.  The first input parameter is a table name with
15842    optional schema, and the second parameter is a column name.  Because
15843    the first parameter is potentially a schema and table, it is not treated
15844    as a double-quoted identifier, meaning it is lower cased by default,
15845    while the second parameter, being just a column name, is treated as
15846    double-quoted and has its case preserved.  The function returns a value
15847    suitably formatted for passing to sequence functions (see <xref
15848    linkend="functions-sequence">).  This association can be modified or
15849    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
15850    probably should have been called
15851    <function>pg_get_owned_sequence</function>; its current name reflects the fact
15852    that it's typically used with <type>serial</> or <type>bigserial</>
15853    columns.)
15854   </para>
15855
15856   <para>
15857    <function>pg_get_userbyid</function> extracts a role's name given
15858    its OID.
15859   </para>
15860
15861   <para>
15862    <function>pg_options_to_table</function> returns the set of storage
15863    option name/value pairs
15864    (<literal>option_name</>/<literal>option_value</>) when passed
15865    <structname>pg_class</>.<structfield>reloptions</> or
15866    <structname>pg_attribute</>.<structfield>attoptions</>.
15867   </para>
15868
15869   <para>
15870    <function>pg_tablespace_databases</function> allows a tablespace to be
15871    examined. It returns the set of OIDs of databases that have objects stored
15872    in the tablespace. If this function returns any rows, the tablespace is not
15873    empty and cannot be dropped. To display the specific objects populating the
15874    tablespace, you will need to connect to the databases identified by
15875    <function>pg_tablespace_databases</function> and query their
15876    <structname>pg_class</> catalogs.
15877   </para>
15878
15879   <para>
15880    <function>pg_typeof</function> returns the OID of the data type of the
15881    value that is passed to it.  This can be helpful for troubleshooting or
15882    dynamically constructing SQL queries.  The function is declared as
15883    returning <type>regtype</>, which is an OID alias type (see
15884    <xref linkend="datatype-oid">); this means that it is the same as an
15885    OID for comparison purposes but displays as a type name.  For example:
15886 <programlisting>
15887 SELECT pg_typeof(33);
15888
15889  pg_typeof 
15890 -----------
15891  integer
15892 (1 row)
15893
15894 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
15895  typlen 
15896 --------
15897       4
15898 (1 row)
15899 </programlisting>
15900   </para>
15901
15902   <para>
15903    The expression <literal>collation for</literal> returns the collation of the
15904    value that is passed to it.  Example:
15905 <programlisting>
15906 SELECT collation for (description) FROM pg_description LIMIT 1;
15907  pg_collation_for 
15908 ------------------
15909  "default"
15910 (1 row)
15911
15912 SELECT collation for ('foo' COLLATE "de_DE");
15913  pg_collation_for 
15914 ------------------
15915  "de_DE"
15916 (1 row)
15917 </programlisting>
15918   The value might be quoted and schema-qualified.  If no collation is derived
15919   for the argument expression, then a null value is returned.  If the argument
15920   is not of a collatable data type, then an error is raised.
15921   </para>
15922
15923   <para>
15924    The <function>to_regclass</function>, <function>to_regproc</function>,
15925    <function>to_regprocedure</function>, <function>to_regoper</function>,
15926    <function>to_regoperator</function>, and <function>to_regtype</function>
15927    functions translate relation, function, operator, and type names to objects
15928    of type <type>regclass</>, <type>regproc</>, <type>regprocedure</type>,
15929    <type>regoper</>, <type>regoperator</type>, and <type>regtype</>,
15930    respectively.  These functions differ from a cast from
15931    text in that they don't accept a numeric OID, and that they return null
15932    rather than throwing an error if the name is not found (or, for
15933    <function>to_regproc</function> and <function>to_regoper</function>, if
15934    the given name matches multiple objects).
15935   </para>
15936
15937    <indexterm>
15938     <primary>pg_describe_object</primary>
15939    </indexterm>
15940
15941    <indexterm>
15942     <primary>pg_identify_object</primary>
15943    </indexterm>
15944
15945    <indexterm>
15946     <primary>pg_identify_object_as_address</primary>
15947    </indexterm>
15948
15949    <indexterm>
15950     <primary>pg_get_object_address</primary>
15951    </indexterm>
15952
15953   <para>
15954    <xref linkend="functions-info-object-table"> lists functions related to
15955    database object identification and addressing.
15956   </para>
15957
15958    <table id="functions-info-object-table">
15959     <title>Object Information and Addressing Functions</title>
15960     <tgroup cols="3">
15961      <thead>
15962       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
15963      </thead>
15964
15965      <tbody>
15966       <row>
15967        <entry><literal><function>pg_describe_object(<parameter>catalog_id</parameter>, <parameter>object_id</parameter>, <parameter>object_sub_id</parameter>)</function></literal></entry>
15968        <entry><type>text</type></entry>
15969        <entry>get description of a database object</entry>
15970       </row>
15971       <row>
15972        <entry><literal><function>pg_identify_object(<parameter>catalog_id</parameter> <type>oid</>, <parameter>object_id</parameter> <type>oid</>, <parameter>object_sub_id</parameter> <type>integer</>)</function></literal></entry>
15973        <entry><parameter>type</> <type>text</>, <parameter>schema</> <type>text</>, <parameter>name</> <type>text</>, <parameter>identity</> <type>text</></entry>
15974        <entry>get identity of a database object</entry>
15975       </row>
15976       <row>
15977        <entry><literal><function>pg_identify_object_as_address(<parameter>catalog_id</parameter> <type>oid</>, <parameter>object_id</parameter> <type>oid</>, <parameter>object_sub_id</parameter> <type>integer</>)</function></literal></entry>
15978        <entry><parameter>type</> <type>text</>, <parameter>name</> <type>text[]</>, <parameter>args</> <type>text[]</></entry>
15979        <entry>get external representation of a database object's address</entry>
15980       </row>
15981       <row>
15982        <entry><literal><function>pg_get_object_address(<parameter>type</parameter> <type>text</>, <parameter>name</parameter> <type>text[]</>, <parameter>args</parameter> <type>text[]</>)</function></literal></entry>
15983        <entry><parameter>catalog_id</> <type>oid</>, <parameter>object_id</> <type>oid</>, <parameter>object_sub_id</> <type>int32</></entry>
15984        <entry>get address of a database object, from its external representation</entry>
15985       </row>
15986      </tbody>
15987     </tgroup>
15988    </table>
15989
15990   <para>
15991    <function>pg_describe_object</function> returns a textual description of a database
15992    object specified by catalog OID, object OID and a (possibly zero) sub-object ID.
15993    This description is intended to be human-readable, and might be translated,
15994    depending on server configuration.
15995    This is useful to determine the identity of an object as stored in the
15996    <structname>pg_depend</structname> catalog.
15997   </para>
15998
15999   <para>
16000    <function>pg_identify_object</function> returns a row containing enough information
16001    to uniquely identify the database object specified by catalog OID, object OID and a
16002    (possibly zero) sub-object ID.  This information is intended to be machine-readable,
16003    and is never translated.
16004    <parameter>type</> identifies the type of database object;
16005    <parameter>schema</> is the schema name that the object belongs in, or
16006    <literal>NULL</> for object types that do not belong to schemas;
16007    <parameter>name</> is the name of the object, quoted if necessary, only
16008    present if it can be used (alongside schema name, if pertinent) as a unique
16009    identifier of the object, otherwise <literal>NULL</>;
16010    <parameter>identity</> is the complete object identity, with the precise format
16011    depending on object type, and each part within the format being
16012    schema-qualified and quoted as necessary.
16013   </para>
16014
16015   <para>
16016    <function>pg_identify_object_as_address</function> returns a row containing
16017    enough information to uniquely identify the database object specified by
16018    catalog OID, object OID and a (possibly zero) sub-object ID.  The returned
16019    information is independent of the current server, that is, it could be used
16020    to identify an identically named object in another server.
16021    <parameter>type</> identifies the type of database object;
16022    <parameter>name</> and <parameter>args</> are text arrays that together
16023    form a reference to the object.  These three columns can be passed to
16024    <function>pg_get_object_address</> to obtain the internal address
16025    of the object.
16026    This function is the inverse of <function>pg_get_object_address</function>.
16027   </para>
16028
16029   <para>
16030    <function>pg_get_object_address</function> returns a row containing enough
16031    information to uniquely identify the database object specified by its
16032    type and object name and argument arrays.  The returned values are the
16033    ones that would be used in system catalogs such as <structname>pg_depend</>
16034    and can be passed to other system functions such as
16035    <function>pg_identify_object</> or <function>pg_describe_object</>.
16036    <parameter>catalog_id</> is the OID of the system catalog containing the
16037    object;
16038    <parameter>object_id</> is the OID of the object itself, and
16039    <parameter>object_sub_id</> is the object sub-ID, or zero if none.
16040    This function is the inverse of <function>pg_identify_object_as_address</function>.
16041   </para>
16042
16043    <indexterm>
16044     <primary>col_description</primary>
16045    </indexterm>
16046
16047    <indexterm>
16048     <primary>obj_description</primary>
16049    </indexterm>
16050
16051    <indexterm>
16052     <primary>shobj_description</primary>
16053    </indexterm>
16054
16055    <indexterm>
16056     <primary>comment</primary>
16057     <secondary sortas="database objects">about database objects</secondary>
16058    </indexterm>
16059
16060    <para>
16061     The functions shown in <xref linkend="functions-info-comment-table">
16062     extract comments previously stored with the <xref linkend="sql-comment">
16063     command.  A null value is returned if no
16064     comment could be found for the specified parameters.
16065    </para>
16066
16067    <table id="functions-info-comment-table">
16068     <title>Comment Information Functions</title>
16069     <tgroup cols="3">
16070      <thead>
16071       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
16072      </thead>
16073
16074      <tbody>
16075       <row>
16076        <entry><literal><function>col_description(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</function></literal></entry>
16077        <entry><type>text</type></entry>
16078        <entry>get comment for a table column</entry>
16079       </row>
16080       <row>
16081        <entry><literal><function>obj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
16082        <entry><type>text</type></entry>
16083        <entry>get comment for a database object</entry>
16084       </row>
16085       <row>
16086        <entry><literal><function>obj_description(<parameter>object_oid</parameter>)</function></literal></entry>
16087        <entry><type>text</type></entry>
16088        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
16089       </row>
16090       <row>
16091        <entry><literal><function>shobj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
16092        <entry><type>text</type></entry>
16093        <entry>get comment for a shared database object</entry>
16094       </row>
16095      </tbody>
16096     </tgroup>
16097    </table>
16098
16099    <para>
16100     <function>col_description</function> returns the comment for a table
16101     column, which is specified by the OID of its table and its column number.
16102     (<function>obj_description</function> cannot be used for table columns
16103     since columns do not have OIDs of their own.)
16104    </para>
16105
16106    <para>
16107     The two-parameter form of <function>obj_description</function> returns the
16108     comment for a database object specified by its OID and the name of the
16109     containing system catalog.  For example,
16110     <literal>obj_description(123456,'pg_class')</literal>
16111     would retrieve the comment for the table with OID 123456.
16112     The one-parameter form of <function>obj_description</function> requires only
16113     the object OID.  It is deprecated since there is no guarantee that
16114     OIDs are unique across different system catalogs; therefore, the wrong
16115     comment might be returned.
16116    </para>
16117
16118    <para>
16119     <function>shobj_description</function> is used just like
16120     <function>obj_description</function> except it is used for retrieving
16121     comments on shared objects.  Some system catalogs are global to all
16122     databases within each cluster, and the descriptions for objects in them
16123     are stored globally as well.
16124    </para>
16125
16126    <indexterm>
16127     <primary>txid_current</primary>
16128    </indexterm>
16129
16130    <indexterm>
16131     <primary>txid_current_snapshot</primary>
16132    </indexterm>
16133
16134    <indexterm>
16135     <primary>txid_snapshot_xip</primary>
16136    </indexterm>
16137
16138    <indexterm>
16139     <primary>txid_snapshot_xmax</primary>
16140    </indexterm>
16141
16142    <indexterm>
16143     <primary>txid_snapshot_xmin</primary>
16144    </indexterm>
16145
16146    <indexterm>
16147     <primary>txid_visible_in_snapshot</primary>
16148    </indexterm>
16149
16150    <para>
16151     The functions shown in <xref linkend="functions-txid-snapshot">
16152     provide server transaction information in an exportable form.  The main
16153     use of these functions is to determine which transactions were committed
16154     between two snapshots.
16155    </para>
16156
16157    <table id="functions-txid-snapshot">
16158     <title>Transaction IDs and Snapshots</title>
16159     <tgroup cols="3">
16160      <thead>
16161       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
16162      </thead>
16163
16164      <tbody>
16165       <row>
16166        <entry><literal><function>txid_current()</function></literal></entry>
16167        <entry><type>bigint</type></entry>
16168        <entry>get current transaction ID</entry>
16169       </row>
16170       <row>
16171        <entry><literal><function>txid_current_snapshot()</function></literal></entry>
16172        <entry><type>txid_snapshot</type></entry>
16173        <entry>get current snapshot</entry>
16174       </row>
16175       <row>
16176        <entry><literal><function>txid_snapshot_xip(<parameter>txid_snapshot</parameter>)</function></literal></entry>
16177        <entry><type>setof bigint</type></entry>
16178        <entry>get in-progress transaction IDs in snapshot</entry>
16179       </row>
16180       <row>
16181        <entry><literal><function>txid_snapshot_xmax(<parameter>txid_snapshot</parameter>)</function></literal></entry>
16182        <entry><type>bigint</type></entry>
16183        <entry>get <literal>xmax</literal> of snapshot</entry>
16184       </row>
16185       <row>
16186        <entry><literal><function>txid_snapshot_xmin(<parameter>txid_snapshot</parameter>)</function></literal></entry>
16187        <entry><type>bigint</type></entry>
16188        <entry>get <literal>xmin</literal> of snapshot</entry>
16189       </row>
16190       <row>
16191        <entry><literal><function>txid_visible_in_snapshot(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</function></literal></entry>
16192        <entry><type>boolean</type></entry>
16193        <entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
16194       </row>
16195      </tbody>
16196     </tgroup>
16197    </table>
16198
16199    <para>
16200     The internal transaction ID type (<type>xid</>) is 32 bits wide and
16201     wraps around every 4 billion transactions.  However, these functions
16202     export a 64-bit format that is extended with an <quote>epoch</> counter
16203     so it will not wrap around during the life of an installation.
16204     The data type used by these functions, <type>txid_snapshot</type>,
16205     stores information about transaction ID
16206     visibility at a particular moment in time.  Its components are
16207     described in <xref linkend="functions-txid-snapshot-parts">.
16208    </para>
16209
16210    <table id="functions-txid-snapshot-parts">
16211     <title>Snapshot Components</title>
16212     <tgroup cols="2">
16213      <thead>
16214       <row>
16215        <entry>Name</entry>
16216        <entry>Description</entry>
16217       </row>
16218      </thead>
16219
16220      <tbody>
16221
16222       <row>
16223        <entry><type>xmin</type></entry>
16224        <entry>
16225          Earliest transaction ID (txid) that is still active.  All earlier
16226          transactions will either be committed and visible, or rolled
16227          back and dead.
16228        </entry>
16229       </row>
16230
16231       <row>
16232        <entry><type>xmax</type></entry>
16233        <entry>
16234         First as-yet-unassigned txid.  All txids greater than or equal to this
16235         are not yet started as of the time of the snapshot, and thus invisible.
16236        </entry>
16237       </row>
16238
16239       <row>
16240        <entry><type>xip_list</type></entry>
16241        <entry>
16242         Active txids at the time of the snapshot.  The list
16243         includes only those active txids between <literal>xmin</>
16244         and <literal>xmax</>; there might be active txids higher
16245         than <literal>xmax</>.  A txid that is <literal>xmin &lt;= txid &lt;
16246         xmax</literal> and not in this list was already completed
16247         at the time of the snapshot, and thus either visible or
16248         dead according to its commit status.  The list does not
16249         include txids of subtransactions.
16250        </entry>
16251       </row>
16252
16253      </tbody>
16254     </tgroup>
16255    </table>
16256
16257    <para>
16258     <type>txid_snapshot</>'s textual representation is
16259     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
16260     For example <literal>10:20:10,14,15</literal> means
16261     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
16262    </para>
16263
16264    <para>
16265     The functions shown in <xref linkend="functions-commit-timestamp">
16266     provide information about transactions that have been already committed.
16267     These functions mainly provide information about when the transactions
16268     were committed. They only provide useful data when
16269     <xref linkend="guc-track-commit-timestamp"> configuration option is enabled
16270     and only for transactions that were committed after it was enabled.
16271    </para>
16272
16273    <table id="functions-commit-timestamp">
16274     <title>Committed transaction information</title>
16275     <tgroup cols="3">
16276      <thead>
16277       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
16278      </thead>
16279
16280      <tbody>
16281       <row>
16282        <entry>
16283         <indexterm><primary>pg_xact_commit_timestamp</primary></indexterm>
16284         <literal><function>pg_xact_commit_timestamp(<parameter>xid</parameter>)</function></literal>
16285        </entry>
16286        <entry><type>timestamp with time zone</type></entry>
16287        <entry>get commit timestamp of a transaction</entry>
16288       </row>
16289
16290       <row>
16291        <entry>
16292         <indexterm><primary>pg_last_committed_xact</primary></indexterm>
16293         <literal><function>pg_last_committed_xact()</function></literal>
16294        </entry>
16295        <entry><parameter>xid</> <type>xid</>, <parameter>timestamp</> <type>timestamp with time zone</></entry>
16296        <entry>get transaction ID and commit timestamp of latest committed transaction</entry>
16297       </row>
16298      </tbody>
16299     </tgroup>
16300    </table>
16301
16302   </sect1>
16303
16304   <sect1 id="functions-admin">
16305    <title>System Administration Functions</title>
16306
16307    <para>
16308     The functions described in this section are used to control and
16309     monitor a <productname>PostgreSQL</> installation.
16310    </para>
16311
16312   <sect2 id="functions-admin-set">
16313    <title>Configuration Settings Functions</title>
16314
16315    <para>
16316     <xref linkend="functions-admin-set-table"> shows the functions
16317     available to query and alter run-time configuration parameters.
16318    </para>
16319
16320    <table id="functions-admin-set-table">
16321     <title>Configuration Settings Functions</title>
16322     <tgroup cols="3">
16323      <thead>
16324       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
16325      </thead>
16326
16327      <tbody>
16328       <row>
16329        <entry>
16330         <indexterm>
16331          <primary>current_setting</primary>
16332         </indexterm>
16333         <literal><function>current_setting(<parameter>setting_name</parameter>)</function></literal>
16334        </entry>
16335        <entry><type>text</type></entry>
16336        <entry>get current value of setting</entry>
16337       </row>
16338       <row>
16339        <entry>
16340         <indexterm>
16341          <primary>set_config</primary>
16342         </indexterm>
16343         <literal><function>set_config(<parameter>setting_name</parameter>,
16344                              <parameter>new_value</parameter>,
16345                              <parameter>is_local</parameter>)</function></literal>
16346        </entry>
16347        <entry><type>text</type></entry>
16348        <entry>set parameter and return new value</entry>
16349       </row>
16350      </tbody>
16351     </tgroup>
16352    </table>
16353
16354    <indexterm>
16355     <primary>SET</primary>
16356    </indexterm>
16357
16358    <indexterm>
16359     <primary>SHOW</primary>
16360    </indexterm>
16361
16362    <indexterm>
16363     <primary>configuration</primary>
16364     <secondary sortas="server">of the server</secondary>
16365     <tertiary>functions</tertiary>
16366    </indexterm>
16367
16368    <para>
16369     The function <function>current_setting</function> yields the
16370     current value of the setting <parameter>setting_name</parameter>.
16371     It corresponds to the <acronym>SQL</acronym> command
16372     <command>SHOW</command>.  An example:
16373 <programlisting>
16374 SELECT current_setting('datestyle');
16375
16376  current_setting
16377 -----------------
16378  ISO, MDY
16379 (1 row)
16380 </programlisting>
16381    </para>
16382
16383    <para>
16384     <function>set_config</function> sets the parameter
16385     <parameter>setting_name</parameter> to
16386     <parameter>new_value</parameter>.  If
16387     <parameter>is_local</parameter> is <literal>true</literal>, the
16388     new value will only apply to the current transaction. If you want
16389     the new value to apply for the current session, use
16390     <literal>false</literal> instead. The function corresponds to the
16391     SQL command <command>SET</command>. An example:
16392 <programlisting>
16393 SELECT set_config('log_statement_stats', 'off', false);
16394
16395  set_config
16396 ------------
16397  off
16398 (1 row)
16399 </programlisting>
16400    </para>
16401
16402   </sect2>
16403
16404   <sect2 id="functions-admin-signal">
16405    <title>Server Signaling Functions</title>
16406
16407    <indexterm>
16408     <primary>pg_cancel_backend</primary>
16409    </indexterm>
16410    <indexterm>
16411     <primary>pg_reload_conf</primary>
16412    </indexterm>
16413    <indexterm>
16414     <primary>pg_rotate_logfile</primary>
16415    </indexterm>
16416    <indexterm>
16417     <primary>pg_terminate_backend</primary>
16418    </indexterm>
16419
16420    <indexterm>
16421     <primary>signal</primary>
16422     <secondary sortas="backend">backend processes</secondary>
16423    </indexterm>
16424
16425    <para>
16426     The functions shown in <xref
16427     linkend="functions-admin-signal-table"> send control signals to
16428     other server processes.  Use of these functions is usually restricted
16429     to superusers, with noted exceptions.
16430    </para>
16431
16432    <table id="functions-admin-signal-table">
16433     <title>Server Signaling Functions</title>
16434     <tgroup cols="3">
16435      <thead>
16436       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
16437       </row>
16438      </thead>
16439
16440      <tbody>
16441       <row>
16442        <entry>
16443         <literal><function>pg_cancel_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
16444         </entry>
16445        <entry><type>boolean</type></entry>
16446        <entry>Cancel a backend's current query.  This is also allowed if the
16447         calling role is a member of the role whose backend is being cancelled,
16448         however only superusers can cancel superuser backends.
16449         </entry>
16450       </row>
16451       <row>
16452        <entry>
16453         <literal><function>pg_reload_conf()</function></literal>
16454         </entry>
16455        <entry><type>boolean</type></entry>
16456        <entry>Cause server processes to reload their configuration files</entry>
16457       </row>
16458       <row>
16459        <entry>
16460         <literal><function>pg_rotate_logfile()</function></literal>
16461         </entry>
16462        <entry><type>boolean</type></entry>
16463        <entry>Rotate server's log file</entry>
16464       </row>
16465       <row>
16466        <entry>
16467         <literal><function>pg_terminate_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
16468         </entry>
16469        <entry><type>boolean</type></entry>
16470        <entry>Terminate a backend.  This is also allowed if the calling role
16471         is a member of the role whose backend is being terminated, however only
16472         superusers can terminate superuser backends.
16473        </entry>
16474       </row>
16475      </tbody>
16476     </tgroup>
16477    </table>
16478
16479    <para>
16480     Each of these functions returns <literal>true</literal> if
16481     successful and <literal>false</literal> otherwise.
16482    </para>
16483
16484    <para>
16485     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
16486     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
16487     respectively) to backend processes identified by process ID.
16488     The process ID of an active backend can be found from
16489     the <structfield>pid</structfield> column of the
16490     <structname>pg_stat_activity</structname> view, or by listing the
16491     <command>postgres</command> processes on the server (using
16492     <application>ps</> on Unix or the <application>Task
16493     Manager</> on <productname>Windows</>).
16494     The role of an active backend can be found from the
16495     <structfield>usename</structfield> column of the
16496     <structname>pg_stat_activity</structname> view.
16497    </para>
16498
16499    <para>
16500     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
16501     to the server, causing configuration files
16502     to be reloaded by all server processes.
16503    </para>
16504
16505    <para>
16506     <function>pg_rotate_logfile</> signals the log-file manager to switch
16507     to a new output file immediately.  This works only when the built-in
16508     log collector is running, since otherwise there is no log-file manager
16509     subprocess.
16510    </para>
16511
16512   </sect2>
16513
16514   <sect2 id="functions-admin-backup">
16515    <title>Backup Control Functions</title>
16516
16517    <indexterm>
16518     <primary>backup</primary>
16519    </indexterm>
16520    <indexterm>
16521     <primary>pg_create_restore_point</primary>
16522    </indexterm>
16523    <indexterm>
16524     <primary>pg_current_xlog_insert_location</primary>
16525    </indexterm>
16526    <indexterm>
16527     <primary>pg_current_xlog_location</primary>
16528    </indexterm>
16529    <indexterm>
16530     <primary>pg_start_backup</primary>
16531    </indexterm>
16532    <indexterm>
16533     <primary>pg_stop_backup</primary>
16534    </indexterm>
16535    <indexterm>
16536     <primary>pg_is_in_backup</primary>
16537    </indexterm>
16538    <indexterm>
16539     <primary>pg_backup_start_time</primary>
16540    </indexterm>
16541    <indexterm>
16542     <primary>pg_switch_xlog</primary>
16543    </indexterm>
16544    <indexterm>
16545     <primary>pg_xlogfile_name</primary>
16546    </indexterm>
16547    <indexterm>
16548     <primary>pg_xlogfile_name_offset</primary>
16549    </indexterm>
16550    <indexterm>
16551     <primary>pg_xlog_location_diff</primary>
16552    </indexterm>
16553
16554    <para>
16555     The functions shown in <xref
16556     linkend="functions-admin-backup-table"> assist in making on-line backups.
16557     These functions cannot be executed during recovery (except
16558     <function>pg_is_in_backup</function>, <function>pg_backup_start_time</function>
16559     and <function>pg_xlog_location_diff</function>).
16560    </para>
16561
16562    <table id="functions-admin-backup-table">
16563     <title>Backup Control Functions</title>
16564     <tgroup cols="3">
16565      <thead>
16566       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
16567       </row>
16568      </thead>
16569
16570      <tbody>
16571       <row>
16572        <entry>
16573         <literal><function>pg_create_restore_point(<parameter>name</> <type>text</>)</function></literal>
16574         </entry>
16575        <entry><type>pg_lsn</type></entry>
16576        <entry>Create a named point for performing restore (restricted to superusers)</entry>
16577       </row>
16578       <row>
16579        <entry>
16580         <literal><function>pg_current_xlog_insert_location()</function></literal>
16581         </entry>
16582        <entry><type>pg_lsn</type></entry>
16583        <entry>Get current transaction log insert location</entry>
16584       </row>
16585       <row>
16586        <entry>
16587         <literal><function>pg_current_xlog_location()</function></literal>
16588         </entry>
16589        <entry><type>pg_lsn</type></entry>
16590        <entry>Get current transaction log write location</entry>
16591       </row>
16592       <row>
16593        <entry>
16594         <literal><function>pg_start_backup(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> </optional>)</function></literal>
16595         </entry>
16596        <entry><type>pg_lsn</type></entry>
16597        <entry>Prepare for performing on-line backup (restricted to superusers or replication roles)</entry>
16598       </row>
16599       <row>
16600        <entry>
16601         <literal><function>pg_stop_backup()</function></literal>
16602         </entry>
16603        <entry><type>pg_lsn</type></entry>
16604        <entry>Finish performing on-line backup (restricted to superusers or replication roles)</entry>
16605       </row>
16606       <row>
16607        <entry>
16608         <literal><function>pg_is_in_backup()</function></literal>
16609         </entry>
16610        <entry><type>bool</type></entry>
16611        <entry>True if an on-line exclusive backup is still in progress.</entry>
16612       </row>
16613       <row>
16614        <entry>
16615         <literal><function>pg_backup_start_time()</function></literal>
16616         </entry>
16617        <entry><type>timestamp with time zone</type></entry>
16618        <entry>Get start time of an on-line exclusive backup in progress.</entry>
16619       </row>
16620       <row>
16621        <entry>
16622         <literal><function>pg_switch_xlog()</function></literal>
16623         </entry>
16624        <entry><type>pg_lsn</type></entry>
16625        <entry>Force switch to a new transaction log file (restricted to superusers)</entry>
16626       </row>
16627       <row>
16628        <entry>
16629         <literal><function>pg_xlogfile_name(<parameter>location</> <type>pg_lsn</>)</function></literal>
16630         </entry>
16631        <entry><type>text</type></entry>
16632        <entry>Convert transaction log location string to file name</entry>
16633       </row>
16634       <row>
16635        <entry>
16636         <literal><function>pg_xlogfile_name_offset(<parameter>location</> <type>pg_lsn</>)</function></literal>
16637         </entry>
16638        <entry><type>text</>, <type>integer</></entry>
16639        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
16640       </row>
16641       <row>
16642        <entry>
16643         <literal><function>pg_xlog_location_diff(<parameter>location</> <type>pg_lsn</>, <parameter>location</> <type>pg_lsn</>)</function></literal>
16644        </entry>
16645        <entry><type>numeric</></entry>
16646        <entry>Calculate the difference between two transaction log locations</entry>
16647       </row>
16648      </tbody>
16649     </tgroup>
16650    </table>
16651
16652    <para>
16653     <function>pg_start_backup</> accepts an
16654     arbitrary user-defined label for the backup.  (Typically this would be
16655     the name under which the backup dump file will be stored.)  The function
16656     writes a backup label file (<filename>backup_label</>) and, if there
16657     are any links in the <filename>pg_tblspc/</> directory, a tablespace map
16658     file (<filename>tablespace_map</>) into the database cluster's data
16659     directory, performs a checkpoint, and then returns the backup's starting
16660     transaction log location as text.  The user can ignore this result value,
16661     but it is provided in case it is useful.
16662 <programlisting>
16663 postgres=# select pg_start_backup('label_goes_here');
16664  pg_start_backup
16665 -----------------
16666  0/D4445B8
16667 (1 row)
16668 </programlisting>
16669     There is an optional second parameter of type <type>boolean</type>.  If <literal>true</>,
16670     it specifies executing <function>pg_start_backup</> as quickly as
16671     possible.  This forces an immediate checkpoint which will cause a
16672     spike in I/O operations, slowing any concurrently executing queries.
16673    </para>
16674
16675    <para>
16676     <function>pg_stop_backup</> removes the label file and, if it exists,
16677     the <filename>tablespace_map</> file created by
16678     <function>pg_start_backup</>, and creates a backup history file in
16679     the transaction log archive area.  The history file includes the label given to
16680     <function>pg_start_backup</>, the starting and ending transaction log locations for
16681     the backup, and the starting and ending times of the backup.  The return
16682     value is the backup's ending transaction log location (which again
16683     can be ignored).  After recording the ending location, the current
16684     transaction log insertion
16685     point is automatically advanced to the next transaction log file, so that the
16686     ending transaction log file can be archived immediately to complete the backup.
16687    </para>
16688
16689    <para>
16690     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the
16691     current file to be archived (assuming you are using continuous archiving).
16692     The return value is the ending transaction log location + 1 within the just-completed transaction log file.
16693     If there has been no transaction log activity since the last transaction log switch,
16694     <function>pg_switch_xlog</> does nothing and returns the start location
16695     of the transaction log file currently in use.
16696    </para>
16697
16698    <para>
16699     <function>pg_create_restore_point</> creates a named transaction log
16700     record that can be used as recovery target, and returns the corresponding
16701     transaction log location.  The given name can then be used with
16702     <xref linkend="recovery-target-name"> to specify the point up to which
16703     recovery will proceed.  Avoid creating multiple restore points with the
16704     same name, since recovery will stop at the first one whose name matches
16705     the recovery target.
16706    </para>
16707
16708    <para>
16709     <function>pg_current_xlog_location</> displays the current transaction log write
16710     location in the same format used by the above functions.  Similarly,
16711     <function>pg_current_xlog_insert_location</> displays the current transaction log
16712     insertion point.  The insertion point is the <quote>logical</> end
16713     of the transaction log
16714     at any instant, while the write location is the end of what has actually
16715     been written out from the server's internal buffers.  The write location
16716     is the end of what can be examined from outside the server, and is usually
16717     what you want if you are interested in archiving partially-complete transaction log
16718     files.  The insertion point is made available primarily for server
16719     debugging purposes.  These are both read-only operations and do not
16720     require superuser permissions.
16721    </para>
16722
16723    <para>
16724     You can use <function>pg_xlogfile_name_offset</> to extract the
16725     corresponding transaction log file name and byte offset from the results of any of the
16726     above functions.  For example:
16727 <programlisting>
16728 postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup());
16729         file_name         | file_offset 
16730 --------------------------+-------------
16731  00000001000000000000000D |     4039624
16732 (1 row)
16733 </programlisting>
16734     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
16735     When the given transaction log location is exactly at a transaction log file boundary, both
16736     these functions return the name of the preceding transaction log file.
16737     This is usually the desired behavior for managing transaction log archiving
16738     behavior, since the preceding file is the last one that currently
16739     needs to be archived.
16740    </para>
16741
16742    <para>
16743     <function>pg_xlog_location_diff</> calculates the difference in bytes
16744     between two transaction log locations. It can be used with
16745     <structname>pg_stat_replication</structname> or some functions shown in
16746     <xref linkend="functions-admin-backup-table"> to get the replication lag.
16747    </para>
16748
16749    <para>
16750     For details about proper usage of these functions, see
16751     <xref linkend="continuous-archiving">.
16752    </para>
16753
16754   </sect2>
16755
16756   <sect2 id="functions-recovery-control">
16757    <title>Recovery Control Functions</title>
16758
16759    <indexterm>
16760     <primary>pg_is_in_recovery</primary>
16761    </indexterm>
16762    <indexterm>
16763     <primary>pg_last_xlog_receive_location</primary>
16764    </indexterm>
16765    <indexterm>
16766     <primary>pg_last_xlog_replay_location</primary>
16767    </indexterm>
16768    <indexterm>
16769     <primary>pg_last_xact_replay_timestamp</primary>
16770    </indexterm>
16771
16772    <para>
16773     The functions shown in <xref
16774     linkend="functions-recovery-info-table"> provide information
16775     about the current status of the standby.
16776     These functions may be executed both during recovery and in normal running.
16777    </para>
16778
16779    <table id="functions-recovery-info-table">
16780     <title>Recovery Information Functions</title>
16781     <tgroup cols="3">
16782      <thead>
16783       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
16784       </row>
16785      </thead>
16786
16787      <tbody>
16788       <row>
16789        <entry>
16790         <literal><function>pg_is_in_recovery()</function></literal>
16791         </entry>
16792        <entry><type>bool</type></entry>
16793        <entry>True if recovery is still in progress.
16794        </entry>
16795       </row>
16796       <row>
16797        <entry>
16798         <literal><function>pg_last_xlog_receive_location()</function></literal>
16799         </entry>
16800        <entry><type>pg_lsn</type></entry>
16801        <entry>Get last transaction log location received and synced to disk by
16802         streaming replication. While streaming replication is in progress
16803         this will increase monotonically. If recovery has completed this will
16804         remain static at
16805         the value of the last WAL record received and synced to disk during
16806         recovery. If streaming replication is disabled, or if it has not yet
16807         started, the function returns NULL.
16808        </entry>
16809       </row>
16810       <row>
16811        <entry>
16812         <literal><function>pg_last_xlog_replay_location()</function></literal>
16813         </entry>
16814        <entry><type>pg_lsn</type></entry>
16815        <entry>Get last transaction log location replayed during recovery.
16816         If recovery is still in progress this will increase monotonically.
16817         If recovery has completed then this value will remain static at
16818         the value of the last WAL record applied during that recovery.
16819         When the server has been started normally without recovery
16820         the function returns NULL.
16821        </entry>
16822       </row>
16823       <row>
16824        <entry>
16825         <literal><function>pg_last_xact_replay_timestamp()</function></literal>
16826         </entry>
16827        <entry><type>timestamp with time zone</type></entry>
16828        <entry>Get time stamp of last transaction replayed during recovery.
16829         This is the time at which the commit or abort WAL record for that
16830         transaction was generated on the primary.
16831         If no transactions have been replayed during recovery, this function
16832         returns NULL.  Otherwise, if recovery is still in progress this will
16833         increase monotonically.  If recovery has completed then this value will
16834         remain static at the value of the last transaction applied during that
16835         recovery.  When the server has been started normally without recovery
16836         the function returns NULL.
16837        </entry>
16838       </row>
16839      </tbody>
16840     </tgroup>
16841    </table>
16842
16843    <indexterm>
16844     <primary>pg_is_xlog_replay_paused</primary>
16845    </indexterm>
16846    <indexterm>
16847     <primary>pg_xlog_replay_pause</primary>
16848    </indexterm>
16849    <indexterm>
16850     <primary>pg_xlog_replay_resume</primary>
16851    </indexterm>
16852
16853    <para>
16854     The functions shown in <xref
16855     linkend="functions-recovery-control-table"> control the progress of recovery.
16856     These functions may be executed only during recovery.
16857    </para>
16858
16859    <table id="functions-recovery-control-table">
16860     <title>Recovery Control Functions</title>
16861     <tgroup cols="3">
16862      <thead>
16863       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
16864       </row>
16865      </thead>
16866
16867      <tbody>
16868       <row>
16869        <entry>
16870         <literal><function>pg_is_xlog_replay_paused()</function></literal>
16871         </entry>
16872        <entry><type>bool</type></entry>
16873        <entry>True if recovery is paused.
16874        </entry>
16875       </row>
16876       <row>
16877        <entry>
16878         <literal><function>pg_xlog_replay_pause()</function></literal>
16879         </entry>
16880        <entry><type>void</type></entry>
16881        <entry>Pauses recovery immediately (restricted to superusers).
16882        </entry>
16883       </row>
16884       <row>
16885        <entry>
16886         <literal><function>pg_xlog_replay_resume()</function></literal>
16887         </entry>
16888        <entry><type>void</type></entry>
16889        <entry>Restarts recovery if it was paused (restricted to superusers).
16890        </entry>
16891       </row>
16892      </tbody>
16893     </tgroup>
16894    </table>
16895
16896    <para>
16897     While recovery is paused no further database changes are applied.
16898     If in hot standby, all new queries will see the same consistent snapshot
16899     of the database, and no further query conflicts will be generated until
16900     recovery is resumed.
16901    </para>
16902
16903    <para>
16904     If streaming replication is disabled, the paused state may continue
16905     indefinitely without problem. While streaming replication is in
16906     progress WAL records will continue to be received, which will
16907     eventually fill available disk space, depending upon the duration of
16908     the pause, the rate of WAL generation and available disk space.
16909    </para>
16910
16911   </sect2>
16912
16913   <sect2 id="functions-snapshot-synchronization">
16914    <title>Snapshot Synchronization Functions</title>
16915
16916    <indexterm>
16917      <primary>pg_export_snapshot</primary>
16918    </indexterm>
16919
16920    <para>
16921     <productname>PostgreSQL</> allows database sessions to synchronize their
16922     snapshots. A <firstterm>snapshot</> determines which data is visible to the
16923     transaction that is using the snapshot. Synchronized snapshots are
16924     necessary when two or more sessions need to see identical content in the
16925     database. If two sessions just start their transactions independently,
16926     there is always a possibility that some third transaction commits
16927     between the executions of the two <command>START TRANSACTION</> commands,
16928     so that one session sees the effects of that transaction and the other
16929     does not.
16930    </para>
16931
16932    <para>
16933     To solve this problem, <productname>PostgreSQL</> allows a transaction to
16934     <firstterm>export</> the snapshot it is using.  As long as the exporting
16935     transaction remains open, other transactions can <firstterm>import</> its
16936     snapshot, and thereby be guaranteed that they see exactly the same view
16937     of the database that the first transaction sees.  But note that any
16938     database changes made by any one of these transactions remain invisible
16939     to the other transactions, as is usual for changes made by uncommitted
16940     transactions.  So the transactions are synchronized with respect to
16941     pre-existing data, but act normally for changes they make themselves.
16942    </para>
16943
16944    <para>
16945     Snapshots are exported with the <function>pg_export_snapshot</> function,
16946     shown in <xref linkend="functions-snapshot-synchronization-table">, and
16947     imported with the <xref linkend="sql-set-transaction"> command.
16948    </para>
16949
16950    <table id="functions-snapshot-synchronization-table">
16951     <title>Snapshot Synchronization Functions</title>
16952     <tgroup cols="3">
16953      <thead>
16954       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
16955       </row>
16956      </thead>
16957
16958      <tbody>
16959       <row>
16960        <entry>
16961         <literal><function>pg_export_snapshot()</function></literal>
16962        </entry>
16963        <entry><type>text</type></entry>
16964        <entry>Save the current snapshot and return its identifier</entry>
16965       </row>
16966      </tbody>
16967     </tgroup>
16968    </table>
16969
16970    <para>
16971     The function <function>pg_export_snapshot</> saves the current snapshot
16972     and returns a <type>text</> string identifying the snapshot.  This string
16973     must be passed (outside the database) to clients that want to import the
16974     snapshot.  The snapshot is available for import only until the end of the
16975     transaction that exported it.  A transaction can export more than one
16976     snapshot, if needed.  Note that doing so is only useful in <literal>READ
16977     COMMITTED</> transactions, since in <literal>REPEATABLE READ</> and
16978     higher isolation levels, transactions use the same snapshot throughout
16979     their lifetime.  Once a transaction has exported any snapshots, it cannot
16980     be prepared with <xref linkend="sql-prepare-transaction">.
16981    </para>
16982
16983    <para>
16984     See  <xref linkend="sql-set-transaction"> for details of how to use an
16985     exported snapshot.
16986    </para>
16987   </sect2>
16988
16989   <sect2 id="functions-replication">
16990    <title>Replication Functions</title>
16991
16992    <para>
16993     The functions shown
16994     in <xref linkend="functions-replication-table"> are for
16995     controlling and interacting with replication features.
16996     See <xref linkend="streaming-replication">,
16997     <xref linkend="streaming-replication-slots">, <xref linkend="replication-origins">
16998     for information about the underlying features.  Use of these
16999     functions is restricted to superusers.
17000    </para>
17001
17002    <para>
17003     Many of these functions have equivalent commands in the replication
17004     protocol; see <xref linkend="protocol-replication">.
17005    </para>
17006
17007    <para>
17008     The functions described in <xref linkend="functions-snapshot-synchronization">, <xref
17009     linkend="functions-recovery-control">, and <xref
17010     linkend="functions-admin-backup"> are also relevant for replication.
17011    </para>
17012
17013    <table id="functions-replication-table">
17014     <title>Replication <acronym>SQL</acronym> Functions</title>
17015     <tgroup cols="3">
17016      <thead>
17017       <row>
17018        <entry>Function</entry>
17019        <entry>Return Type</entry>
17020        <entry>Description</entry>
17021       </row>
17022      </thead>
17023      <tbody>
17024       <row>
17025        <entry>
17026         <indexterm>
17027          <primary>pg_create_physical_replication_slot</primary>
17028         </indexterm>
17029         <literal><function>pg_create_physical_replication_slot(<parameter>slot_name</parameter> <type>name</type>)</function></literal>
17030        </entry>
17031        <entry>
17032         (<parameter>slot_name</parameter> <type>name</type>, <parameter>xlog_position</parameter> <type>pg_lsn</type>)
17033        </entry>
17034        <entry>
17035         Creates a new physical replication slot named
17036         <parameter>slot_name</parameter>. Streaming changes from a physical slot
17037         is only possible with the streaming-replication protocol - see <xref
17038         linkend="protocol-replication">. Corresponds to the replication protocol
17039         command <literal>CREATE_REPLICATION_SLOT ... PHYSICAL</literal>.
17040        </entry>
17041       </row>
17042       <row>
17043        <entry>
17044         <indexterm>
17045          <primary>pg_drop_replication_slot</primary>
17046         </indexterm>
17047         <literal><function>pg_drop_replication_slot(<parameter>slot_name</parameter> <type>name</type>)</function></literal>
17048        </entry>
17049        <entry>
17050         <type>void</type>
17051        </entry>
17052        <entry>
17053         Drops the physical or logical replication slot
17054         named <parameter>slot_name</parameter>. Same as replication protocol
17055         command <literal>DROP_REPLICATION_SLOT</>.
17056        </entry>
17057       </row>
17058
17059       <row>
17060        <entry>
17061         <indexterm>
17062          <primary>pg_create_logical_replication_slot</primary>
17063         </indexterm>
17064         <literal><function>pg_create_logical_replication_slot(<parameter>slot_name</parameter> <type>name</type>, <parameter>plugin</parameter> <type>name</type>)</function></literal>
17065        </entry>
17066        <entry>
17067         (<parameter>slot_name</parameter> <type>name</type>, <parameter>xlog_position</parameter> <type>pg_lsn</type>)
17068        </entry>
17069        <entry>
17070         Creates a new logical (decoding) replication slot named
17071         <parameter>slot_name</parameter> using the output plugin
17072         <parameter>plugin</parameter>.  A call to this function has the same
17073         effect as the replication protocol command
17074         <literal>CREATE_REPLICATION_SLOT ... LOGICAL</literal>.
17075        </entry>
17076       </row>
17077
17078       <row>
17079        <entry>
17080         <indexterm>
17081          <primary>pg_logical_slot_get_changes</primary>
17082         </indexterm>
17083         <literal><function>pg_logical_slot_get_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
17084        </entry>
17085        <entry>
17086         (<parameter>location</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>text</type>)
17087        </entry>
17088        <entry>
17089         Returns changes in the slot <parameter>slot_name</parameter>, starting
17090         from the point at which since changes have been consumed last.  If
17091         <parameter>upto_lsn</> and <parameter>upto_nchanges</> are NULL,
17092         logical decoding will continue until end of WAL.  If
17093         <parameter>upto_lsn</> is non-NULL, decoding will include only
17094         those transactions which commit prior to the specified LSN.  If
17095         <parameter>upto_nchanges</parameter> is non-NULL, decoding will
17096         stop when the number of rows produced by decoding exceeds
17097         the specified value.  Note, however, that the actual number of
17098         rows returned may be larger, since this limit is only checked after
17099         adding the rows produced when decoding each new transaction commit.
17100        </entry>
17101       </row>
17102
17103       <row>
17104        <entry>
17105         <indexterm>
17106          <primary>pg_logical_slot_peek_changes</primary>
17107         </indexterm>
17108         <literal><function>pg_logical_slot_peek_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
17109        </entry>
17110        <entry>
17111         (<parameter>location</parameter> <type>text</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>text</type>)
17112        </entry>
17113        <entry>
17114         Behaves just like
17115         the <function>pg_logical_slot_get_changes()</function> function,
17116         except that changes are not consumed; that is, they will be returned
17117         again on future calls.
17118        </entry>
17119       </row>
17120
17121       <row>
17122        <entry>
17123         <indexterm>
17124          <primary>pg_logical_slot_get_binary_changes</primary>
17125         </indexterm>
17126         <literal><function>pg_logical_slot_get_binary_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
17127        </entry>
17128        <entry>
17129         (<parameter>location</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>bytea</type>)
17130        </entry>
17131        <entry>
17132         Behaves just like
17133         the <function>pg_logical_slot_get_changes()</function> function,
17134         except that changes are returned as <type>bytea</type>.
17135        </entry>
17136       </row>
17137
17138       <row>
17139        <entry>
17140         <indexterm>
17141          <primary>pg_logical_slot_peek_binary_changes</primary>
17142         </indexterm>
17143         <literal><function>pg_logical_slot_peek_binary_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
17144        </entry>
17145        <entry>
17146         (<parameter>location</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>bytea</type>)
17147        </entry>
17148        <entry>
17149         Behaves just like
17150         the <function>pg_logical_slot_get_changes()</function> function,
17151         except that changes are returned as <type>bytea</type> and that
17152         changes are not consumed; that is, they will be returned again
17153         on future calls.
17154        </entry>
17155       </row>
17156
17157       <row id="pg-replication-origin-create">
17158        <entry>
17159         <indexterm>
17160          <primary>pg_replication_origin_create</primary>
17161         </indexterm>
17162         <literal><function>pg_replication_origin_create(<parameter>node_name</parameter> <type>text</type>)</function></literal>
17163        </entry>
17164        <entry>
17165         <parameter>internal_id</parameter> <type>oid</type>
17166        </entry>
17167        <entry>
17168         Create a replication origin with the passed in external
17169         name, and create an internal id for it.
17170        </entry>
17171       </row>
17172
17173       <row id="pg-replication-origin-drop">
17174        <entry>
17175         <indexterm>
17176          <primary>pg_replication_origin_drop</primary>
17177         </indexterm>
17178         <literal><function>pg_replication_origin_drop(<parameter>node_name</parameter> <type>text</type>)</function></literal>
17179        </entry>
17180        <entry>
17181         void
17182        </entry>
17183        <entry>
17184         Delete a previously created replication origin, including the
17185         associated replay progress.
17186        </entry>
17187       </row>
17188
17189       <row>
17190        <entry>
17191         <indexterm>
17192          <primary>pg_replication_origin_oid</primary>
17193         </indexterm>
17194         <literal><function>pg_replication_origin_oid(<parameter>node_name</parameter> <type>text</type>)</function></literal>
17195        </entry>
17196        <entry>
17197         <parameter>internal_id</parameter> <type>oid</type>
17198        </entry>
17199        <entry>
17200         Lookup replication origin by name and return the internal id. If no
17201         corresponding replication origin is found an error is thrown.
17202        </entry>
17203       </row>
17204
17205       <row id="pg-replication-origin-session-setup">
17206        <entry>
17207         <indexterm>
17208          <primary>pg_replication_origin_session_setup</primary>
17209         </indexterm>
17210         <literal><function>pg_replication_origin_setup_session(<parameter>node_name</parameter> <type>text</type>)</function></literal>
17211        </entry>
17212        <entry>
17213         void
17214        </entry>
17215        <entry>
17216         Configure the current session to be replaying from the passed in
17217         origin, allowing replay progress to be tracked.  Use
17218         <function>pg_replication_origin_session_reset</function> to revert.
17219         Can only be used if no previous origin is configured.
17220        </entry>
17221       </row>
17222
17223       <row>
17224        <entry>
17225         <indexterm>
17226          <primary>pg_replication_origin_session_reset</primary>
17227         </indexterm>
17228         <literal><function>pg_replication_origin_session_reset()</function></literal>
17229        </entry>
17230        <entry>
17231         void
17232        </entry>
17233        <entry>
17234         Cancel the effects
17235         of <function>pg_replication_origin_session_setup()</function>.
17236        </entry>
17237       </row>
17238
17239       <row>
17240        <entry>
17241         <indexterm>
17242          <primary>pg_replication_session_is_setup</primary>
17243         </indexterm>
17244         <literal><function>pg_replication_session_is_setup()</function></literal>
17245        </entry>
17246        <entry>
17247         bool
17248        </entry>
17249        <entry>
17250         Has a replication origin been configured in the current session?
17251        </entry>
17252       </row>
17253
17254       <row id="pg-replication-origin-session-progress">
17255        <entry>
17256         <indexterm>
17257          <primary>pg_replication_origin_session_progress</primary>
17258         </indexterm>
17259         <literal><function>pg_replication_origin_progress(<parameter>flush</parameter> <type>bool</type>)</function></literal>
17260        </entry>
17261        <entry>
17262         pg_lsn
17263        </entry>
17264        <entry>
17265         Return the replay position for the replication origin configured in
17266         the current session. The parameter <parameter>flush</parameter>
17267         determines whether the corresponding local transaction will be
17268         guaranteed to have been flushed to disk or not.
17269        </entry>
17270       </row>
17271
17272       <row id="pg-replication-origin-xact-setup">
17273        <entry>
17274         <indexterm>
17275          <primary>pg_replication_origin_xact_setup</primary>
17276         </indexterm>
17277         <literal><function>pg_replication_origin_xact_setup(<parameter>origin_lsn</parameter> <type>pg_lsn</type>, <parameter>origin_timestamp</parameter> <type>timestamptz</type>)</function></literal>
17278        </entry>
17279        <entry>
17280         void
17281        </entry>
17282        <entry>
17283         Mark the current transaction to be replaying a transaction that has
17284         committed at the passed in <acronym>LSN</acronym> and timestamp. Can
17285         only be called when a replication origin has previously been
17286         configured using
17287         <function>pg_replication_origin_session_setup()</function>.
17288        </entry>
17289       </row>
17290
17291       <row id="pg-replication-origin-xact-reset">
17292        <entry>
17293         <indexterm>
17294          <primary>pg_replication_origin_xact_reset</primary>
17295         </indexterm>
17296         <literal><function>pg_replication_origin_xact_reset()</function></literal>
17297        </entry>
17298        <entry>
17299         void
17300        </entry>
17301        <entry>
17302         Cancel the effects of
17303         <function>pg_replication_origin_xact_setup()</function>.
17304        </entry>
17305       </row>
17306
17307       <row>
17308        <entry>
17309         <indexterm>
17310          <primary>pg_replication_origin_advance</primary>
17311         </indexterm>
17312         <literal>pg_replication_origin_advance<function>(<parameter>node_name</parameter> <type>text</type>, <parameter>pos</parameter> <type>pg_lsn</type>)</function></literal>
17313        </entry>
17314        <entry>
17315         void
17316        </entry>
17317        <entry>
17318         Set replication progress for the passed in node to the passed in
17319         position. This primarily is useful for setting up the initial position
17320         or a new position after configuration changes and similar. Be aware
17321         that careless use of this function can lead to inconsistently
17322         replicated data.
17323        </entry>
17324       </row>
17325
17326       <row id="pg-replication-origin-progress">
17327        <entry>
17328         <indexterm>
17329          <primary>pg_replication_origin_progress</primary>
17330         </indexterm>
17331         <literal><function>pg_replication_origin_progress(<parameter>node_name</parameter> <type>text</type>, <parameter>flush</parameter> <type>bool</type>)</function></literal>
17332        </entry>
17333        <entry>
17334         pg_lsn
17335        </entry>
17336        <entry>
17337         Return the replay position for the passed in replication origin. The
17338         parameter <parameter>flush</parameter> determines whether the
17339         corresponding local transaction will be guaranteed to have been
17340         flushed to disk or not.
17341        </entry>
17342       </row>
17343
17344      </tbody>
17345     </tgroup>
17346    </table>
17347
17348   </sect2>
17349
17350   <sect2 id="functions-admin-dbobject">
17351    <title>Database Object Management Functions</title>
17352
17353    <para>
17354     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
17355     the disk space usage of database objects.
17356    </para>
17357
17358    <indexterm>
17359     <primary>pg_column_size</primary>
17360    </indexterm>
17361    <indexterm>
17362     <primary>pg_database_size</primary>
17363    </indexterm>
17364    <indexterm>
17365     <primary>pg_indexes_size</primary>
17366    </indexterm>
17367    <indexterm>
17368     <primary>pg_relation_size</primary>
17369    </indexterm>
17370    <indexterm>
17371     <primary>pg_size_pretty</primary>
17372    </indexterm>
17373    <indexterm>
17374     <primary>pg_table_size</primary>
17375    </indexterm>
17376    <indexterm>
17377     <primary>pg_tablespace_size</primary>
17378    </indexterm>
17379    <indexterm>
17380     <primary>pg_total_relation_size</primary>
17381    </indexterm>
17382
17383    <table id="functions-admin-dbsize">
17384     <title>Database Object Size Functions</title>
17385     <tgroup cols="3">
17386      <thead>
17387       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
17388       </row>
17389      </thead>
17390
17391      <tbody>
17392       <row>
17393        <entry><literal><function>pg_column_size(<type>any</type>)</function></literal></entry>
17394        <entry><type>int</type></entry>
17395        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
17396       </row>
17397       <row>
17398        <entry>
17399         <literal><function>pg_database_size(<type>oid</type>)</function></literal>
17400         </entry>
17401        <entry><type>bigint</type></entry>
17402        <entry>Disk space used by the database with the specified OID</entry>
17403       </row>
17404       <row>
17405        <entry>
17406         <literal><function>pg_database_size(<type>name</type>)</function></literal>
17407         </entry>
17408        <entry><type>bigint</type></entry>
17409        <entry>Disk space used by the database with the specified name</entry>
17410       </row>
17411       <row>
17412        <entry>
17413         <literal><function>pg_indexes_size(<type>regclass</type>)</function></literal>
17414         </entry>
17415        <entry><type>bigint</type></entry>
17416        <entry>
17417         Total disk space used by indexes attached to the specified table
17418        </entry>
17419       </row>
17420       <row>
17421        <entry>
17422         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</function></literal>
17423         </entry>
17424        <entry><type>bigint</type></entry>
17425        <entry>
17426         Disk space used by the specified fork (<literal>'main'</literal>,
17427         <literal>'fsm'</literal>, <literal>'vm'</>, or <literal>'init'</>)
17428         of the specified table or index
17429        </entry>
17430       </row>
17431       <row>
17432        <entry>
17433         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
17434         </entry>
17435        <entry><type>bigint</type></entry>
17436        <entry>
17437         Shorthand for <literal>pg_relation_size(..., 'main')</literal>
17438        </entry>
17439       </row>
17440       <row>
17441        <entry>
17442         <literal><function>pg_size_pretty(<type>bigint</type>)</function></literal>
17443         </entry>
17444        <entry><type>text</type></entry>
17445        <entry>
17446          Converts a size in bytes expressed as a 64-bit integer into a
17447          human-readable format with size units
17448        </entry>
17449       </row>
17450       <row>
17451        <entry>
17452         <literal><function>pg_size_pretty(<type>numeric</type>)</function></literal>
17453         </entry>
17454        <entry><type>text</type></entry>
17455        <entry>
17456          Converts a size in bytes expressed as a numeric value into a
17457          human-readable format with size units
17458        </entry>
17459       </row>
17460       <row>
17461        <entry>
17462         <literal><function>pg_table_size(<type>regclass</type>)</function></literal>
17463         </entry>
17464        <entry><type>bigint</type></entry>
17465        <entry>
17466         Disk space used by the specified table, excluding indexes
17467         (but including TOAST, free space map, and visibility map)
17468        </entry>
17469       </row>
17470       <row>
17471        <entry>
17472         <literal><function>pg_tablespace_size(<type>oid</type>)</function></literal>
17473         </entry>
17474        <entry><type>bigint</type></entry>
17475        <entry>Disk space used by the tablespace with the specified OID</entry>
17476       </row>
17477       <row>
17478        <entry>
17479         <literal><function>pg_tablespace_size(<type>name</type>)</function></literal>
17480         </entry>
17481        <entry><type>bigint</type></entry>
17482        <entry>Disk space used by the tablespace with the specified name</entry>
17483       </row>
17484       <row>
17485        <entry>
17486         <literal><function>pg_total_relation_size(<type>regclass</type>)</function></literal>
17487         </entry>
17488        <entry><type>bigint</type></entry>
17489        <entry>
17490         Total disk space used by the specified table,
17491         including all indexes and <acronym>TOAST</> data
17492        </entry>
17493       </row>
17494      </tbody>
17495     </tgroup>
17496    </table>
17497
17498    <para>
17499     <function>pg_column_size</> shows the space used to store any individual
17500     data value.
17501    </para>
17502
17503    <para>
17504     <function>pg_total_relation_size</> accepts the OID or name of a
17505     table or toast table, and returns the total on-disk space used for
17506     that table, including all associated indexes.  This function is
17507     equivalent to <function>pg_table_size</function>
17508     <literal>+</> <function>pg_indexes_size</function>.
17509    </para>
17510
17511    <para>
17512     <function>pg_table_size</> accepts the OID or name of a table and
17513     returns the disk space needed for that table, exclusive of indexes.
17514     (TOAST space, free space map, and visibility map are included.)
17515    </para>
17516
17517    <para>
17518     <function>pg_indexes_size</> accepts the OID or name of a table and
17519     returns the total disk space used by all the indexes attached to that
17520     table.
17521    </para>
17522
17523    <para>
17524     <function>pg_database_size</function> and <function>pg_tablespace_size</>
17525     accept the OID or name of a database or tablespace, and return the total
17526     disk space used therein.  To use <function>pg_database_size</function>,
17527     you must have <literal>CONNECT</> permission on the specified database
17528     (which is granted by default).  To use <function>pg_tablespace_size</>,
17529     you must have <literal>CREATE</> permission on the specified tablespace,
17530     unless it is the default tablespace for the current database.
17531    </para>
17532
17533    <para>
17534     <function>pg_relation_size</> accepts the OID or name of a table, index
17535     or toast table, and returns the on-disk size in bytes of one fork of
17536     that relation.  (Note that for most purposes it is more convenient to
17537     use the higher-level functions <function>pg_total_relation_size</>
17538     or <function>pg_table_size</>, which sum the sizes of all forks.)
17539     With one argument, it returns the size of the main data fork of the
17540     relation.  The second argument can be provided to specify which fork
17541     to examine:
17542     <itemizedlist spacing="compact">
17543      <listitem>
17544       <para>
17545        <literal>'main'</literal> returns the size of the main
17546        data fork of the relation.
17547       </para>
17548      </listitem>
17549      <listitem>
17550       <para>
17551        <literal>'fsm'</literal> returns the size of the Free Space Map
17552        (see <xref linkend="storage-fsm">) associated with the relation.
17553       </para>
17554      </listitem>
17555      <listitem>
17556       <para>
17557        <literal>'vm'</literal> returns the size of the Visibility Map
17558        (see <xref linkend="storage-vm">) associated with the relation.
17559       </para>
17560      </listitem>
17561      <listitem>
17562       <para>
17563        <literal>'init'</literal> returns the size of the initialization
17564        fork, if any, associated with the relation.
17565       </para>
17566      </listitem>
17567     </itemizedlist>
17568    </para>
17569
17570    <para>
17571     <function>pg_size_pretty</> can be used to format the result of one of
17572     the other functions in a human-readable way, using kB, MB, GB or TB as
17573     appropriate.
17574    </para>
17575
17576    <para>
17577     The functions above that operate on tables or indexes accept a
17578     <type>regclass</> argument, which is simply the OID of the table or index
17579     in the <structname>pg_class</> system catalog.  You do not have to look up
17580     the OID by hand, however, since the <type>regclass</> data type's input
17581     converter will do the work for you.  Just write the table name enclosed in
17582     single quotes so that it looks like a literal constant.  For compatibility
17583     with the handling of ordinary <acronym>SQL</acronym> names, the string
17584     will be converted to lower case unless it contains double quotes around
17585     the table name.
17586    </para>
17587
17588    <para>
17589     If an OID that does not represent an existing object is passed as
17590     argument to one of the above functions, NULL is returned.
17591    </para>
17592
17593    <para>
17594     The functions shown in <xref linkend="functions-admin-dblocation"> assist
17595     in identifying the specific disk files associated with database objects.
17596    </para>
17597
17598    <indexterm>
17599     <primary>pg_relation_filenode</primary>
17600    </indexterm>
17601    <indexterm>
17602     <primary>pg_relation_filepath</primary>
17603    </indexterm>
17604    <indexterm>
17605     <primary>pg_filenode_relation</primary>
17606    </indexterm>
17607
17608    <table id="functions-admin-dblocation">
17609     <title>Database Object Location Functions</title>
17610     <tgroup cols="3">
17611      <thead>
17612       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
17613       </row>
17614      </thead>
17615
17616      <tbody>
17617       <row>
17618        <entry>
17619         <literal><function>pg_relation_filenode(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
17620         </entry>
17621        <entry><type>oid</type></entry>
17622        <entry>
17623         Filenode number of the specified relation
17624        </entry>
17625       </row>
17626       <row>
17627        <entry>
17628         <literal><function>pg_relation_filepath(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
17629         </entry>
17630        <entry><type>text</type></entry>
17631        <entry>
17632         File path name of the specified relation
17633        </entry>
17634       </row>
17635       <row>
17636        <entry>
17637         <literal><function>pg_filenode_relation(<parameter>tablespace</parameter> <type>oid</type>, <parameter>filenode</parameter> <type>oid</type>)</function></literal>
17638         </entry>
17639        <entry><type>regclass</type></entry>
17640        <entry>
17641         Find the relation associated with a given tablespace and filenode
17642        </entry>
17643       </row>
17644      </tbody>
17645     </tgroup>
17646    </table>
17647
17648    <para>
17649     <function>pg_relation_filenode</> accepts the OID or name of a table,
17650     index, sequence, or toast table, and returns the <quote>filenode</> number
17651     currently assigned to it.  The filenode is the base component of the file
17652     name(s) used for the relation (see <xref linkend="storage-file-layout">
17653     for more information).  For most tables the result is the same as
17654     <structname>pg_class</>.<structfield>relfilenode</>, but for certain
17655     system catalogs <structfield>relfilenode</> is zero and this function must
17656     be used to get the correct value.  The function returns NULL if passed
17657     a relation that does not have storage, such as a view.
17658    </para>
17659
17660    <para>
17661     <function>pg_relation_filepath</> is similar to
17662     <function>pg_relation_filenode</>, but it returns the entire file path name
17663     (relative to the database cluster's data directory <varname>PGDATA</>) of
17664     the relation.
17665    </para>
17666
17667    <para>
17668     <function>pg_filenode_relation</> is the reverse of
17669     <function>pg_relation_filenode</>. Given a <quote>tablespace</> OID and
17670     a <quote>filenode</>, it returns the associated relation's OID. For a table
17671     in the database's default tablespace, the tablespace can be specified as 0.
17672    </para>
17673
17674   </sect2>
17675
17676   <sect2 id="functions-admin-genfile">
17677    <title>Generic File Access Functions</title>
17678
17679    <para>
17680     The functions shown in <xref
17681     linkend="functions-admin-genfile-table"> provide native access to
17682     files on the machine hosting the server. Only files within the
17683     database cluster directory and the <varname>log_directory</> can be
17684     accessed.  Use a relative path for files in the cluster directory,
17685     and a path matching the <varname>log_directory</> configuration setting
17686     for log files.  Use of these functions is restricted to superusers.
17687    </para>
17688
17689    <table id="functions-admin-genfile-table">
17690     <title>Generic File Access Functions</title>
17691     <tgroup cols="3">
17692      <thead>
17693       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
17694       </row>
17695      </thead>
17696
17697      <tbody>
17698       <row>
17699        <entry>
17700         <literal><function>pg_ls_dir(<parameter>dirname</> <type>text</>)</function></literal>
17701        </entry>
17702        <entry><type>setof text</type></entry>
17703        <entry>List the contents of a directory</entry>
17704       </row>
17705       <row>
17706        <entry>
17707         <literal><function>pg_read_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
17708        </entry>
17709        <entry><type>text</type></entry>
17710        <entry>Return the contents of a text file</entry>
17711       </row>
17712       <row>
17713        <entry>
17714         <literal><function>pg_read_binary_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
17715        </entry>
17716        <entry><type>bytea</type></entry>
17717        <entry>Return the contents of a file</entry>
17718       </row>
17719       <row>
17720        <entry>
17721         <literal><function>pg_stat_file(<parameter>filename</> <type>text</>)</function></literal>
17722        </entry>
17723        <entry><type>record</type></entry>
17724        <entry>Return information about a file</entry>
17725       </row>
17726      </tbody>
17727     </tgroup>
17728    </table>
17729
17730    <indexterm>
17731     <primary>pg_ls_dir</primary>
17732    </indexterm>
17733    <para>
17734     <function>pg_ls_dir</> returns all the names in the specified
17735     directory, except the special entries <quote><literal>.</></> and
17736     <quote><literal>..</></>.
17737    </para>
17738
17739    <indexterm>
17740     <primary>pg_read_file</primary>
17741    </indexterm>
17742    <para>
17743     <function>pg_read_file</> returns part of a text file, starting
17744     at the given <parameter>offset</>, returning at most <parameter>length</>
17745     bytes (less if the end of file is reached first).  If <parameter>offset</>
17746     is negative, it is relative to the end of the file.
17747     If <parameter>offset</> and <parameter>length</> are omitted, the entire
17748     file is returned.  The bytes read from the file are interpreted as a string
17749     in the server encoding; an error is thrown if they are not valid in that
17750     encoding.
17751    </para>
17752
17753    <indexterm>
17754     <primary>pg_read_binary_file</primary>
17755    </indexterm>
17756    <para>
17757     <function>pg_read_binary_file</> is similar to
17758     <function>pg_read_file</>, except that the result is a <type>bytea</type> value;
17759     accordingly, no encoding checks are performed.
17760     In combination with the <function>convert_from</> function, this function
17761     can be used to read a file in a specified encoding:
17762 <programlisting>
17763 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
17764 </programlisting>
17765    </para>
17766
17767    <indexterm>
17768     <primary>pg_stat_file</primary>
17769    </indexterm>
17770    <para>
17771     <function>pg_stat_file</> returns a record containing the file
17772     size, last accessed time stamp, last modified time stamp,
17773     last file status change time stamp (Unix platforms only),
17774     file creation time stamp (Windows only), and a <type>boolean</type>
17775     indicating if it is a directory.  Typical usages include:
17776 <programlisting>
17777 SELECT * FROM pg_stat_file('filename');
17778 SELECT (pg_stat_file('filename')).modification;
17779 </programlisting>
17780    </para>
17781
17782   </sect2>
17783
17784   <sect2 id="functions-advisory-locks">
17785    <title>Advisory Lock Functions</title>
17786
17787    <para>
17788     The functions shown in <xref linkend="functions-advisory-locks-table">
17789     manage advisory locks.  For details about proper use of these functions,
17790     see <xref linkend="advisory-locks">.
17791    </para>
17792
17793    <table id="functions-advisory-locks-table">
17794     <title>Advisory Lock Functions</title>
17795     <tgroup cols="3">
17796      <thead>
17797       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
17798       </row>
17799      </thead>
17800
17801      <tbody>
17802       <row>
17803        <entry>
17804         <literal><function>pg_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
17805        </entry>
17806        <entry><type>void</type></entry>
17807        <entry>Obtain exclusive session level advisory lock</entry>
17808       </row>
17809       <row>
17810        <entry>
17811         <literal><function>pg_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17812        </entry>
17813        <entry><type>void</type></entry>
17814        <entry>Obtain exclusive session level advisory lock</entry>
17815       </row>
17816       <row>
17817        <entry>
17818         <literal><function>pg_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
17819        </entry>
17820        <entry><type>void</type></entry>
17821        <entry>Obtain shared session level advisory lock</entry>
17822       </row>
17823       <row>
17824        <entry>
17825         <literal><function>pg_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17826        </entry>
17827        <entry><type>void</type></entry>
17828        <entry>Obtain shared session level advisory lock</entry>
17829       </row>
17830       <row>
17831        <entry>
17832         <literal><function>pg_advisory_unlock(<parameter>key</> <type>bigint</>)</function></literal>
17833        </entry>
17834        <entry><type>boolean</type></entry>
17835        <entry>Release an exclusive session level advisory lock</entry>
17836       </row>
17837       <row>
17838        <entry>
17839         <literal><function>pg_advisory_unlock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17840        </entry>
17841        <entry><type>boolean</type></entry>
17842        <entry>Release an exclusive session level advisory lock</entry>
17843       </row>
17844       <row>
17845        <entry>
17846         <literal><function>pg_advisory_unlock_all()</function></literal>
17847        </entry>
17848        <entry><type>void</type></entry>
17849        <entry>Release all session level advisory locks held by the current session</entry>
17850       </row>
17851       <row>
17852        <entry>
17853         <literal><function>pg_advisory_unlock_shared(<parameter>key</> <type>bigint</>)</function></literal>
17854        </entry>
17855        <entry><type>boolean</type></entry>
17856        <entry>Release a shared session level advisory lock</entry>
17857       </row>
17858       <row>
17859        <entry>
17860         <literal><function>pg_advisory_unlock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17861        </entry>
17862        <entry><type>boolean</type></entry>
17863        <entry>Release a shared session level advisory lock</entry>
17864       </row>
17865       <row>
17866        <entry>
17867         <literal><function>pg_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
17868        </entry>
17869        <entry><type>void</type></entry>
17870        <entry>Obtain exclusive transaction level advisory lock</entry>
17871       </row>
17872       <row>
17873        <entry>
17874         <literal><function>pg_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17875        </entry>
17876        <entry><type>void</type></entry>
17877        <entry>Obtain exclusive transaction level advisory lock</entry>
17878       </row>
17879       <row>
17880        <entry>
17881         <literal><function>pg_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
17882        </entry>
17883        <entry><type>void</type></entry>
17884        <entry>Obtain shared transaction level advisory lock</entry>
17885       </row>
17886       <row>
17887        <entry>
17888         <literal><function>pg_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17889        </entry>
17890        <entry><type>void</type></entry>
17891        <entry>Obtain shared transaction level advisory lock</entry>
17892       </row>
17893       <row>
17894        <entry>
17895         <literal><function>pg_try_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
17896        </entry>
17897        <entry><type>boolean</type></entry>
17898        <entry>Obtain exclusive session level advisory lock if available</entry>
17899       </row>
17900       <row>
17901        <entry>
17902         <literal><function>pg_try_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17903        </entry>
17904        <entry><type>boolean</type></entry>
17905        <entry>Obtain exclusive session level advisory lock if available</entry>
17906       </row>
17907       <row>
17908        <entry>
17909         <literal><function>pg_try_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
17910        </entry>
17911        <entry><type>boolean</type></entry>
17912        <entry>Obtain shared session level advisory lock if available</entry>
17913       </row>
17914       <row>
17915        <entry>
17916         <literal><function>pg_try_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17917        </entry>
17918        <entry><type>boolean</type></entry>
17919        <entry>Obtain shared session level advisory lock if available</entry>
17920       </row>
17921       <row>
17922        <entry>
17923         <literal><function>pg_try_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
17924        </entry>
17925        <entry><type>boolean</type></entry>
17926        <entry>Obtain exclusive transaction level advisory lock if available</entry>
17927       </row>
17928       <row>
17929        <entry>
17930         <literal><function>pg_try_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17931        </entry>
17932        <entry><type>boolean</type></entry>
17933        <entry>Obtain exclusive transaction level advisory lock if available</entry>
17934       </row>
17935       <row>
17936        <entry>
17937         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
17938        </entry>
17939        <entry><type>boolean</type></entry>
17940        <entry>Obtain shared transaction level advisory lock if available</entry>
17941       </row>
17942       <row>
17943        <entry>
17944         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
17945        </entry>
17946        <entry><type>boolean</type></entry>
17947        <entry>Obtain shared transaction level advisory lock if available</entry>
17948       </row>
17949      </tbody>
17950     </tgroup>
17951    </table>
17952
17953    <indexterm>
17954     <primary>pg_advisory_lock</primary>
17955    </indexterm>
17956    <para>
17957     <function>pg_advisory_lock</> locks an application-defined resource,
17958     which can be identified either by a single 64-bit key value or two
17959     32-bit key values (note that these two key spaces do not overlap).
17960     If another session already holds a lock on the same resource identifier,
17961     this function will wait until the resource becomes available.  The lock
17962     is exclusive.  Multiple lock requests stack, so that if the same resource
17963     is locked three times it must then be unlocked three times to be
17964     released for other sessions' use.
17965    </para>
17966
17967    <indexterm>
17968     <primary>pg_advisory_lock_shared</primary>
17969    </indexterm>
17970    <para>
17971     <function>pg_advisory_lock_shared</> works the same as
17972     <function>pg_advisory_lock</>,
17973     except the lock can be shared with other sessions requesting shared locks.
17974     Only would-be exclusive lockers are locked out.
17975    </para>
17976
17977    <indexterm>
17978     <primary>pg_try_advisory_lock</primary>
17979    </indexterm>
17980    <para>
17981     <function>pg_try_advisory_lock</> is similar to
17982     <function>pg_advisory_lock</>, except the function will not wait for the
17983     lock to become available.  It will either obtain the lock immediately and
17984     return <literal>true</>, or return <literal>false</> if the lock cannot be
17985     acquired immediately.
17986    </para>
17987
17988    <indexterm>
17989     <primary>pg_try_advisory_lock_shared</primary>
17990    </indexterm>
17991    <para>
17992     <function>pg_try_advisory_lock_shared</> works the same as
17993     <function>pg_try_advisory_lock</>, except it attempts to acquire
17994     a shared rather than an exclusive lock.
17995    </para>
17996
17997    <indexterm>
17998     <primary>pg_advisory_unlock</primary>
17999    </indexterm>
18000    <para>
18001     <function>pg_advisory_unlock</> will release a previously-acquired
18002     exclusive session level advisory lock.  It
18003     returns <literal>true</> if the lock is successfully released.
18004     If the lock was not held, it will return <literal>false</>,
18005     and in addition, an SQL warning will be reported by the server.
18006    </para>
18007
18008    <indexterm>
18009     <primary>pg_advisory_unlock_shared</primary>
18010    </indexterm>
18011    <para>
18012     <function>pg_advisory_unlock_shared</> works the same as
18013     <function>pg_advisory_unlock</>,
18014     except it releases a shared session level advisory lock.
18015    </para>
18016
18017    <indexterm>
18018     <primary>pg_advisory_unlock_all</primary>
18019    </indexterm>
18020    <para>
18021     <function>pg_advisory_unlock_all</> will release all session level advisory
18022     locks held by the current session.  (This function is implicitly invoked
18023     at session end, even if the client disconnects ungracefully.)
18024    </para>
18025
18026    <indexterm>
18027     <primary>pg_advisory_xact_lock</primary>
18028    </indexterm>
18029    <para>
18030     <function>pg_advisory_xact_lock</> works the same as
18031     <function>pg_advisory_lock</>, except the lock is automatically released
18032     at the end of the current transaction and cannot be released explicitly.
18033    </para>
18034
18035    <indexterm>
18036     <primary>pg_advisory_xact_lock_shared</primary>
18037    </indexterm>
18038    <para>
18039     <function>pg_advisory_xact_lock_shared</> works the same as
18040     <function>pg_advisory_lock_shared</>, except the lock is automatically released
18041     at the end of the current transaction and cannot be released explicitly.
18042    </para>
18043
18044    <indexterm>
18045     <primary>pg_try_advisory_xact_lock</primary>
18046    </indexterm>
18047    <para>
18048     <function>pg_try_advisory_xact_lock</> works the same as
18049     <function>pg_try_advisory_lock</>, except the lock, if acquired,
18050     is automatically released at the end of the current transaction and
18051     cannot be released explicitly.
18052    </para>
18053
18054    <indexterm>
18055     <primary>pg_try_advisory_xact_lock_shared</primary>
18056    </indexterm>
18057    <para>
18058     <function>pg_try_advisory_xact_lock_shared</> works the same as
18059     <function>pg_try_advisory_lock_shared</>, except the lock, if acquired,
18060     is automatically released at the end of the current transaction and
18061     cannot be released explicitly.
18062    </para>
18063
18064   </sect2>
18065
18066   </sect1>
18067
18068   <sect1 id="functions-trigger">
18069    <title>Trigger Functions</title>
18070
18071    <indexterm>
18072      <primary>suppress_redundant_updates_trigger</primary>
18073    </indexterm>
18074
18075    <para>
18076       Currently <productname>PostgreSQL</> provides one built in trigger
18077       function, <function>suppress_redundant_updates_trigger</>,
18078       which will prevent any update
18079       that does not actually change the data in the row from taking place, in
18080       contrast to the normal behavior which always performs the update
18081       regardless of whether or not the data has changed. (This normal behavior
18082       makes updates run faster, since no checking is required, and is also
18083       useful in certain cases.)
18084     </para>
18085
18086     <para>
18087       Ideally, you should normally avoid running updates that don't actually
18088       change the data in the record. Redundant updates can cost considerable
18089       unnecessary time, especially if there are lots of indexes to alter,
18090       and space in dead rows that will eventually have to be vacuumed.
18091       However, detecting such situations in client code is not
18092       always easy, or even possible, and writing expressions to detect
18093       them can be error-prone. An alternative is to use
18094       <function>suppress_redundant_updates_trigger</>, which will skip
18095       updates that don't change the data. You should use this with care,
18096       however. The trigger takes a small but non-trivial time for each record,
18097       so if most of the records affected by an update are actually changed,
18098       use of this trigger will actually make the update run slower.
18099     </para>
18100
18101     <para>
18102       The <function>suppress_redundant_updates_trigger</> function can be
18103       added to a table like this:
18104 <programlisting>
18105 CREATE TRIGGER z_min_update
18106 BEFORE UPDATE ON tablename
18107 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
18108 </programlisting>
18109       In most cases, you would want to fire this trigger last for each row.
18110       Bearing in mind that triggers fire in name order, you would then
18111       choose a trigger name that comes after the name of any other trigger
18112       you might have on the table.
18113     </para>
18114     <para>
18115        For more information about creating triggers, see
18116         <xref linkend="SQL-CREATETRIGGER">.
18117     </para>
18118   </sect1>
18119
18120   <sect1 id="functions-event-triggers">
18121    <title>Event Trigger Functions</title>
18122
18123    <para>
18124     <productname>PostgreSQL</> provides these helper functions
18125     to retrieve information from event triggers.
18126    </para>
18127
18128    <para>
18129     For more information about event triggers,
18130     see <xref linkend="event-triggers">.
18131    </para>
18132
18133   <sect2 id="pg-event-trigger-ddl-command-end-functions">
18134    <title>Capturing Changes at Command End</title>
18135
18136    <indexterm>
18137     <primary>pg_event_trigger_ddl_commands</primary>
18138    </indexterm>
18139
18140    <para>
18141     <function>pg_event_trigger_ddl_commands</> returns a list of
18142     <acronym>DDL</acronym> commands executed by each user action,
18143     when invoked in a function attached to a
18144     <literal>ddl_command_end</> event trigger.  If called in any other
18145     context, an error is raised.
18146     <function>pg_event_trigger_ddl_commands</> returns one row for each
18147     base command executed; some commands that are a single SQL sentence
18148     may return more than one row.  This function returns the following
18149     columns:
18150
18151     <informaltable>
18152      <tgroup cols="3">
18153       <thead>
18154        <row>
18155         <entry>Name</entry>
18156         <entry>Type</entry>
18157         <entry>Description</entry>
18158        </row>
18159       </thead>
18160
18161       <tbody>
18162        <row>
18163         <entry><literal>classid</literal></entry>
18164         <entry><type>Oid</type></entry>
18165         <entry>OID of catalog the object belongs in</entry>
18166        </row>
18167        <row>
18168         <entry><literal>objid</literal></entry>
18169         <entry><type>Oid</type></entry>
18170         <entry>OID of the object in the catalog</entry>
18171        </row>
18172        <row>
18173         <entry><literal>objsubid</literal></entry>
18174         <entry><type>integer</type></entry>
18175         <entry>Object sub-id (e.g. attribute number for columns)</entry>
18176        </row>
18177        <row>
18178         <entry><literal>command_tag</literal></entry>
18179         <entry><type>text</type></entry>
18180         <entry>command tag</entry>
18181        </row>
18182        <row>
18183         <entry><literal>object_type</literal></entry>
18184         <entry><type>text</type></entry>
18185         <entry>Type of the object</entry>
18186        </row>
18187        <row>
18188         <entry><literal>schema_name</literal></entry>
18189         <entry><type>text</type></entry>
18190         <entry>
18191          Name of the schema the object belongs in, if any; otherwise <literal>NULL</>.
18192          No quoting is applied.
18193         </entry>
18194        </row>
18195        <row>
18196         <entry><literal>object_identity</literal></entry>
18197         <entry><type>text</type></entry>
18198         <entry>
18199          Text rendering of the object identity, schema-qualified. Each and every
18200          identifier present in the identity is quoted if necessary.
18201         </entry>
18202        </row>
18203        <row>
18204         <entry><literal>in_extension</literal></entry>
18205         <entry><type>bool</type></entry>
18206         <entry>whether the command is part of an extension script</entry>
18207        </row>
18208        <row>
18209         <entry><literal>command</literal></entry>
18210         <entry><type>pg_ddl_command</type></entry>
18211         <entry>
18212          A complete representation of the command, in internal format.
18213          This cannot be output directly, but it can be passed to other
18214          functions to obtain different pieces of information about the
18215          command.
18216         </entry>
18217        </row>
18218       </tbody>
18219      </tgroup>
18220     </informaltable>
18221    </para>
18222   </sect2>
18223
18224   <sect2 id="pg-event-trigger-sql-drop-functions">
18225    <title>Processing Objects Dropped by a DDL Command</title>
18226
18227    <indexterm>
18228      <primary>pg_event_trigger_dropped_objects</primary>
18229    </indexterm>
18230
18231    <para>
18232     <function>pg_event_trigger_dropped_objects</> returns a list of all objects
18233     dropped by the command in whose <literal>sql_drop</> event it is called.
18234     If called in any other context,
18235     <function>pg_event_trigger_dropped_objects</> raises an error.
18236     <function>pg_event_trigger_dropped_objects</> returns the following columns:
18237
18238     <informaltable>
18239      <tgroup cols="3">
18240       <thead>
18241        <row>
18242         <entry>Name</entry>
18243         <entry>Type</entry>
18244         <entry>Description</entry>
18245        </row>
18246       </thead>
18247
18248       <tbody>
18249        <row>
18250         <entry><literal>classid</literal></entry>
18251         <entry><type>Oid</type></entry>
18252         <entry>OID of catalog the object belonged in</entry>
18253        </row>
18254        <row>
18255         <entry><literal>objid</literal></entry>
18256         <entry><type>Oid</type></entry>
18257         <entry>OID the object had within the catalog</entry>
18258        </row>
18259        <row>
18260         <entry><literal>objsubid</literal></entry>
18261         <entry><type>int32</type></entry>
18262         <entry>Object sub-id (e.g. attribute number for columns)</entry>
18263        </row>
18264        <row>
18265         <entry><literal>original</literal></entry>
18266         <entry><type>bool</type></entry>
18267         <entry>Flag used to identify the root object(s) of the deletion</entry>
18268        </row>
18269        <row>
18270         <entry><literal>normal</literal></entry>
18271         <entry><type>bool</type></entry>
18272         <entry>
18273          Flag indicating that there's a normal dependency relationship
18274          in the dependency graph leading to this object
18275         </entry>
18276        </row>
18277        <row>
18278         <entry><literal>is_temporary</literal></entry>
18279         <entry><type>bool</type></entry>
18280         <entry>
18281          Flag indicating that the object was a temporary object.
18282         </entry>
18283        </row>
18284        <row>
18285         <entry><literal>object_type</literal></entry>
18286         <entry><type>text</type></entry>
18287         <entry>Type of the object</entry>
18288        </row>
18289        <row>
18290         <entry><literal>schema_name</literal></entry>
18291         <entry><type>text</type></entry>
18292         <entry>
18293          Name of the schema the object belonged in, if any; otherwise <literal>NULL</>.
18294          No quoting is applied.
18295         </entry>
18296        </row>
18297        <row>
18298         <entry><literal>object_name</literal></entry>
18299         <entry><type>text</type></entry>
18300         <entry>
18301          Name of the object, if the combination of schema and name can be
18302          used as a unique identifier for the object; otherwise <literal>NULL</>.
18303          No quoting is applied, and name is never schema-qualified.
18304         </entry>
18305        </row>
18306        <row>
18307         <entry><literal>object_identity</literal></entry>
18308         <entry><type>text</type></entry>
18309         <entry>
18310          Text rendering of the object identity, schema-qualified. Each and every
18311          identifier present in the identity is quoted if necessary.
18312         </entry>
18313        </row>
18314        <row>
18315         <entry><literal>address_names</literal></entry>
18316         <entry><type>text[]</type></entry>
18317         <entry>
18318          An array that, together with <literal>object_type</literal> and
18319          <literal>address_args</literal>,
18320          can be used by the <function>pg_get_object_address()</function> to
18321          recreate the object address in a remote server containing an
18322          identically named object of the same kind.
18323         </entry>
18324        </row>
18325        <row>
18326         <entry><literal>address_args</literal></entry>
18327         <entry><type>text[]</type></entry>
18328         <entry>
18329          Complement for <literal>address_names</literal> above.
18330         </entry>
18331        </row>
18332       </tbody>
18333      </tgroup>
18334     </informaltable>
18335    </para>
18336
18337    <para>
18338     The <function>pg_event_trigger_dropped_objects</> function can be used
18339     in an event trigger like this:
18340 <programlisting>
18341 CREATE FUNCTION test_event_trigger_for_drops()
18342         RETURNS event_trigger LANGUAGE plpgsql AS $$
18343 DECLARE
18344     obj record;
18345 BEGIN
18346     FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
18347     LOOP
18348         RAISE NOTICE '% dropped object: % %.% %',
18349                      tg_tag,
18350                      obj.object_type,
18351                      obj.schema_name,
18352                      obj.object_name,
18353                      obj.object_identity;
18354     END LOOP;
18355 END
18356 $$;
18357 CREATE EVENT TRIGGER test_event_trigger_for_drops
18358    ON sql_drop
18359    EXECUTE PROCEDURE test_event_trigger_for_drops();
18360 </programlisting>
18361     </para>
18362   </sect2>
18363
18364   <sect2 id="pg-event-trigger-table-rewrite-functions">
18365    <title>Handling a Table Rewrite Event</title>
18366
18367    <para>
18368     The functions shown in
18369     <xref linkend="functions-event-trigger-table-rewrite">
18370     provide information about a table for which a
18371     <literal>table_rewrite</> event has just been called.
18372     If called in any other context, an error is raised.
18373    </para>
18374
18375    <table id="functions-event-trigger-table-rewrite">
18376     <title>Table Rewrite information</title>
18377     <tgroup cols="3">
18378      <thead>
18379       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
18380      </thead>
18381
18382      <tbody>
18383       <row>
18384        <entry>
18385         <indexterm><primary>pg_event_trigger_table_rewrite_oid</primary></indexterm>
18386         <literal><function>pg_event_trigger_table_rewrite_oid()</function></literal>
18387        </entry>
18388        <entry><type>Oid</type></entry>
18389        <entry>The Oid of the table about to be rewritten.</entry>
18390       </row>
18391
18392       <row>
18393        <entry>
18394         <indexterm><primary>pg_event_trigger_table_rewrite_reason</primary></indexterm>
18395         <literal><function>pg_event_trigger_table_rewrite_reason()</function></literal>
18396        </entry>
18397        <entry><type>int</type></entry>
18398        <entry>
18399         The reason code(s) explaining the reason for rewriting. The exact
18400         meaning of the codes is release dependent.
18401        </entry>
18402       </row>
18403      </tbody>
18404     </tgroup>
18405    </table>
18406
18407    <para>
18408     The <function>pg_event_trigger_table_rewrite_oid</> function can be used
18409     in an event trigger like this:
18410 <programlisting>
18411 CREATE FUNCTION test_event_trigger_table_rewrite_oid()
18412  RETURNS event_trigger
18413  LANGUAGE plpgsql AS
18414 $$
18415 BEGIN
18416   RAISE NOTICE 'rewriting table % for reason %',
18417                 pg_event_trigger_table_rewrite_oid()::regclass,
18418                 pg_event_trigger_table_rewrite_reason();
18419 END;
18420 $$;
18421
18422 CREATE EVENT TRIGGER test_table_rewrite_oid
18423                   ON table_rewrite
18424    EXECUTE PROCEDURE test_event_trigger_table_rewrite_oid();
18425 </programlisting>
18426     </para>
18427   </sect2>
18428   </sect1>
18429
18430 </chapter>