]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
Add timezone offset output option to to_char()
[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>random</primary>
835         </indexterm>
836         <literal><function>random()</function></literal>
837        </entry>
838        <entry><type>dp</type></entry>
839        <entry>random value in the range 0.0 &lt;= x &lt; 1.0</entry>
840        <entry><literal>random()</literal></entry>
841        <entry></entry>
842       </row>
843
844       <row>
845        <entry>
846         <indexterm>
847          <primary>round</primary>
848         </indexterm>
849         <literal><function>round(<type>dp</type> or <type>numeric</type>)</function></literal>
850        </entry>
851        <entry>(same as input)</entry>
852        <entry>round to nearest integer</entry>
853        <entry><literal>round(42.4)</literal></entry>
854        <entry><literal>42</literal></entry>
855       </row>
856
857       <row>
858        <entry><literal><function>round(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
859        <entry><type>numeric</type></entry>
860        <entry>round to <parameter>s</parameter> decimal places</entry>
861        <entry><literal>round(42.4382, 2)</literal></entry>
862        <entry><literal>42.44</literal></entry>
863       </row>
864
865       <row>
866        <entry>
867         <indexterm>
868          <primary>setseed</primary>
869         </indexterm>
870         <literal><function>setseed(<type>dp</type>)</function></literal>
871        </entry>
872        <entry><type>void</type></entry>
873        <entry>set seed for subsequent <literal>random()</literal> calls (value between -1.0 and
874        1.0, inclusive)</entry>
875        <entry><literal>setseed(0.54823)</literal></entry>
876        <entry></entry>
877       </row>
878
879       <row>
880        <entry>
881         <indexterm>
882          <primary>sign</primary>
883         </indexterm>
884         <literal><function>sign(<type>dp</type> or <type>numeric</type>)</function></literal>
885        </entry>
886        <entry>(same as input)</entry>
887        <entry>sign of the argument (-1, 0, +1)</entry>
888        <entry><literal>sign(-8.4)</literal></entry>
889        <entry><literal>-1</literal></entry>
890       </row>
891
892       <row>
893        <entry>
894         <indexterm>
895          <primary>sqrt</primary>
896         </indexterm>
897         <literal><function>sqrt(<type>dp</type> or <type>numeric</type>)</function></literal>
898        </entry>
899        <entry>(same as input)</entry>
900        <entry>square root</entry>
901        <entry><literal>sqrt(2.0)</literal></entry>
902        <entry><literal>1.4142135623731</literal></entry>
903       </row>
904
905       <row>
906        <entry>
907         <indexterm>
908          <primary>trunc</primary>
909         </indexterm>
910         <literal><function>trunc(<type>dp</type> or <type>numeric</type>)</function></literal>
911        </entry>
912        <entry>(same as input)</entry>
913        <entry>truncate toward zero</entry>
914        <entry><literal>trunc(42.8)</literal></entry>
915        <entry><literal>42</literal></entry>
916       </row>
917
918       <row>
919        <entry><literal><function>trunc(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
920        <entry><type>numeric</type></entry>
921        <entry>truncate to <parameter>s</parameter> decimal places</entry>
922        <entry><literal>trunc(42.4382, 2)</literal></entry>
923        <entry><literal>42.43</literal></entry>
924       </row>
925
926       <row>
927        <entry>
928         <indexterm>
929          <primary>width_bucket</primary>
930         </indexterm>
931         <literal><function>width_bucket(<parameter>op</parameter> <type>numeric</type>, <parameter>b1</parameter> <type>numeric</type>, <parameter>b2</parameter> <type>numeric</type>, <parameter>count</parameter> <type>int</type>)</function></literal>
932        </entry>
933        <entry><type>int</type></entry>
934        <entry>return the bucket to which <parameter>operand</> would
935        be assigned in an equidepth histogram with <parameter>count</>
936        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
937        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
938        <entry><literal>3</literal></entry>
939       </row>
940
941       <row>
942        <entry><literal><function>width_bucket(<parameter>op</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>
943        <entry><type>int</type></entry>
944        <entry>return the bucket to which <parameter>operand</> would
945        be assigned in an equidepth histogram with <parameter>count</>
946        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
947        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
948        <entry><literal>3</literal></entry>
949       </row>
950      </tbody>
951     </tgroup>
952    </table>
953
954   <para>
955    Finally, <xref linkend="functions-math-trig-table"> shows the
956    available trigonometric functions.  All trigonometric functions
957    take arguments and return values of type <type>double
958    precision</type>. Trigonometric functions arguments are expressed
959    in radians. Inverse functions return values are expressed in
960    radians.  See unit transformation functions
961    <literal><function>radians()</function></literal> and
962    <literal><function>degrees()</function></literal> above.
963   </para>
964
965    <table id="functions-math-trig-table">
966     <title>Trigonometric Functions</title>
967
968     <tgroup cols="2">
969      <thead>
970       <row>
971        <entry>Function</entry>
972        <entry>Description</entry>
973       </row>
974      </thead>
975
976      <tbody>
977       <row>
978        <entry>
979         <indexterm>
980          <primary>acos</primary>
981         </indexterm><literal><function>acos(<replaceable>x</replaceable>)</function></literal>
982        </entry>
983        <entry>inverse cosine</entry>
984       </row>
985
986       <row>
987        <entry>
988         <indexterm>
989          <primary>asin</primary>
990         </indexterm>
991         <literal><function>asin(<replaceable>x</replaceable>)</function></literal>
992        </entry>
993        <entry>inverse sine</entry>
994       </row>
995
996       <row>
997        <entry>
998         <indexterm>
999          <primary>atan</primary>
1000         </indexterm>
1001         <literal><function>atan(<replaceable>x</replaceable>)</function></literal>
1002        </entry>
1003        <entry>inverse tangent</entry>
1004       </row>
1005
1006       <row>
1007        <entry>
1008         <indexterm>
1009          <primary>atan2</primary>
1010         </indexterm>
1011         <literal><function>atan2(<replaceable>y</replaceable>,
1012         <replaceable>x</replaceable>)</function></literal>
1013        </entry>
1014        <entry>inverse tangent of
1015         <literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
1016       </row>
1017
1018       <row>
1019        <entry>
1020         <indexterm>
1021          <primary>cos</primary>
1022         </indexterm>
1023         <literal><function>cos(<replaceable>x</replaceable>)</function></literal>
1024        </entry>
1025        <entry>cosine</entry>
1026       </row>
1027
1028       <row>
1029        <entry>
1030         <indexterm>
1031          <primary>cot</primary>
1032         </indexterm>
1033         <literal><function>cot(<replaceable>x</replaceable>)</function></literal>
1034        </entry>
1035        <entry>cotangent</entry>
1036       </row>
1037
1038       <row>
1039        <entry>
1040         <indexterm>
1041          <primary>sin</primary>
1042         </indexterm>
1043         <literal><function>sin(<replaceable>x</replaceable>)</function></literal>
1044        </entry>
1045        <entry>sine</entry>
1046       </row>
1047
1048       <row>
1049        <entry>
1050         <indexterm>
1051          <primary>tan</primary>
1052         </indexterm>
1053         <literal><function>tan(<replaceable>x</replaceable>)</function></literal>
1054        </entry>
1055        <entry>tangent</entry>
1056       </row>
1057      </tbody>
1058     </tgroup>
1059    </table>
1060
1061   </sect1>
1062
1063
1064   <sect1 id="functions-string">
1065    <title>String Functions and Operators</title>
1066
1067    <para>
1068     This section describes functions and operators for examining and
1069     manipulating string values.  Strings in this context include values
1070     of the types <type>character</type>, <type>character varying</type>,
1071     and <type>text</type>.  Unless otherwise noted, all
1072     of the functions listed below work on all of these types, but be
1073     wary of potential effects of automatic space-padding when using the
1074     <type>character</type> type.  Some functions also exist
1075     natively for the bit-string types.
1076    </para>
1077
1078    <para>
1079     <acronym>SQL</acronym> defines some string functions that use
1080     key words, rather than commas, to separate
1081     arguments.  Details are in
1082     <xref linkend="functions-string-sql">.
1083     <productname>PostgreSQL</> also provides versions of these functions
1084     that use the regular function invocation syntax
1085     (see <xref linkend="functions-string-other">).
1086    </para>
1087
1088    <note>
1089     <para>
1090      Before <productname>PostgreSQL</productname> 8.3, these functions would
1091      silently accept values of several non-string data types as well, due to
1092      the presence of implicit coercions from those data types to
1093      <type>text</>.  Those coercions have been removed because they frequently
1094      caused surprising behaviors.  However, the string concatenation operator
1095      (<literal>||</>) still accepts non-string input, so long as at least one
1096      input is of a string type, as shown in <xref
1097      linkend="functions-string-sql">.  For other cases, insert an explicit
1098      coercion to <type>text</> if you need to duplicate the previous behavior.
1099     </para>
1100    </note>
1101
1102    <table id="functions-string-sql">
1103     <title><acronym>SQL</acronym> String Functions and Operators</title>
1104     <tgroup cols="5">
1105      <thead>
1106       <row>
1107        <entry>Function</entry>
1108        <entry>Return Type</entry>
1109        <entry>Description</entry>
1110        <entry>Example</entry>
1111        <entry>Result</entry>
1112       </row>
1113      </thead>
1114
1115      <tbody>
1116       <row>
1117        <entry><literal><parameter>string</parameter> <literal>||</literal>
1118         <parameter>string</parameter></literal></entry>
1119        <entry> <type>text</type> </entry>
1120        <entry>
1121         String concatenation
1122         <indexterm>
1123          <primary>character string</primary>
1124          <secondary>concatenation</secondary>
1125         </indexterm>
1126        </entry>
1127        <entry><literal>'Post' || 'greSQL'</literal></entry>
1128        <entry><literal>PostgreSQL</literal></entry>
1129       </row>
1130
1131       <row>
1132        <entry>
1133         <literal><parameter>string</parameter> <literal>||</literal>
1134         <parameter>non-string</parameter></literal>
1135         or
1136         <literal><parameter>non-string</parameter> <literal>||</literal>
1137         <parameter>string</parameter></literal>
1138        </entry>
1139        <entry> <type>text</type> </entry>
1140        <entry>
1141         String concatenation with one non-string input
1142        </entry>
1143        <entry><literal>'Value: ' || 42</literal></entry>
1144        <entry><literal>Value: 42</literal></entry>
1145       </row>
1146
1147       <row>
1148        <entry>
1149         <indexterm>
1150          <primary>bit_length</primary>
1151         </indexterm>
1152         <literal><function>bit_length(<parameter>string</parameter>)</function></literal>
1153        </entry>
1154        <entry><type>int</type></entry>
1155        <entry>Number of bits in string</entry>
1156        <entry><literal>bit_length('jose')</literal></entry>
1157        <entry><literal>32</literal></entry>
1158       </row>
1159
1160       <row>
1161        <entry>
1162         <indexterm>
1163          <primary>char_length</primary>
1164         </indexterm>
1165         <literal><function>char_length(<parameter>string</parameter>)</function></literal> or <literal><function>character_length(<parameter>string</parameter>)</function></literal>
1166        </entry>
1167        <entry><type>int</type></entry>
1168        <entry>
1169         Number of characters in string
1170         <indexterm>
1171          <primary>character string</primary>
1172          <secondary>length</secondary>
1173         </indexterm>
1174         <indexterm>
1175          <primary>length</primary>
1176          <secondary sortas="character string">of a character string</secondary>
1177          <see>character string, length</see>
1178         </indexterm>
1179        </entry>
1180        <entry><literal>char_length('jose')</literal></entry>
1181        <entry><literal>4</literal></entry>
1182       </row>
1183
1184       <row>
1185        <entry>
1186         <indexterm>
1187          <primary>lower</primary>
1188         </indexterm>
1189         <literal><function>lower(<parameter>string</parameter>)</function></literal>
1190        </entry>
1191        <entry><type>text</type></entry>
1192        <entry>Convert string to lower case</entry>
1193        <entry><literal>lower('TOM')</literal></entry>
1194        <entry><literal>tom</literal></entry>
1195       </row>
1196
1197       <row>
1198        <entry>
1199         <indexterm>
1200          <primary>octet_length</primary>
1201         </indexterm>
1202         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
1203        </entry>
1204        <entry><type>int</type></entry>
1205        <entry>Number of bytes in string</entry>
1206        <entry><literal>octet_length('jose')</literal></entry>
1207        <entry><literal>4</literal></entry>
1208       </row>
1209
1210       <row>
1211        <entry>
1212         <indexterm>
1213          <primary>overlay</primary>
1214         </indexterm>
1215         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
1216        </entry>
1217        <entry><type>text</type></entry>
1218        <entry>
1219         Replace substring
1220        </entry>
1221        <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
1222        <entry><literal>Thomas</literal></entry>
1223       </row>
1224
1225       <row>
1226        <entry>
1227         <indexterm>
1228          <primary>position</primary>
1229         </indexterm>
1230         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
1231        </entry>
1232        <entry><type>int</type></entry>
1233        <entry>Location of specified substring</entry>
1234        <entry><literal>position('om' in 'Thomas')</literal></entry>
1235        <entry><literal>3</literal></entry>
1236       </row>
1237
1238       <row>
1239        <entry>
1240         <indexterm>
1241          <primary>substring</primary>
1242         </indexterm>
1243         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
1244        </entry>
1245        <entry><type>text</type></entry>
1246        <entry>
1247         Extract substring
1248        </entry>
1249        <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
1250        <entry><literal>hom</literal></entry>
1251       </row>
1252
1253       <row>
1254        <entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</function></literal></entry>
1255        <entry><type>text</type></entry>
1256        <entry>
1257         Extract substring matching POSIX regular expression. See
1258         <xref linkend="functions-matching"> for more information on pattern
1259         matching.
1260        </entry>
1261        <entry><literal>substring('Thomas' from '...$')</literal></entry>
1262        <entry><literal>mas</literal></entry>
1263       </row>
1264
1265       <row>
1266        <entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</function></literal></entry>
1267        <entry><type>text</type></entry>
1268        <entry>
1269         Extract substring matching <acronym>SQL</acronym> regular expression.
1270         See <xref linkend="functions-matching"> for more information on
1271         pattern matching.
1272        </entry>
1273        <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
1274        <entry><literal>oma</literal></entry>
1275       </row>
1276
1277       <row>
1278        <entry>
1279         <indexterm>
1280          <primary>trim</primary>
1281         </indexterm>
1282         <literal><function>trim(<optional>leading | trailing | both</optional>
1283         <optional><parameter>characters</parameter></optional> from
1284         <parameter>string</parameter>)</function></literal>
1285        </entry>
1286        <entry><type>text</type></entry>
1287        <entry>
1288         Remove the longest string containing only the
1289         <parameter>characters</parameter> (a space by default) from the
1290         start/end/both ends of the <parameter>string</parameter>
1291        </entry>
1292        <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
1293        <entry><literal>Tom</literal></entry>
1294       </row>
1295
1296       <row>
1297        <entry>
1298         <indexterm>
1299          <primary>upper</primary>
1300         </indexterm>
1301         <literal><function>upper(<parameter>string</parameter>)</function></literal>
1302        </entry>
1303        <entry><type>text</type></entry>
1304        <entry>Convert string to upper case</entry>
1305        <entry><literal>upper('tom')</literal></entry>
1306        <entry><literal>TOM</literal></entry>
1307       </row>
1308      </tbody>
1309     </tgroup>
1310    </table>
1311
1312    <para>
1313     Additional string manipulation functions are available and are
1314     listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
1315     <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
1316    </para>
1317
1318    <table id="functions-string-other">
1319     <title>Other String Functions</title>
1320     <tgroup cols="5">
1321      <thead>
1322       <row>
1323        <entry>Function</entry>
1324        <entry>Return Type</entry>
1325        <entry>Description</entry>
1326        <entry>Example</entry>
1327        <entry>Result</entry>
1328       </row>
1329      </thead>
1330
1331      <tbody>
1332       <row>
1333        <entry>
1334         <indexterm>
1335          <primary>ascii</primary>
1336         </indexterm>
1337         <literal><function>ascii(<parameter>string</parameter>)</function></literal>
1338        </entry>
1339        <entry><type>int</type></entry>
1340        <entry>
1341         <acronym>ASCII</acronym> code of the first character of the
1342         argument.  For <acronym>UTF8</acronym> returns the Unicode code
1343         point of the character.  For other multibyte encodings, the
1344         argument must be an <acronym>ASCII</acronym> character.
1345        </entry>
1346        <entry><literal>ascii('x')</literal></entry>
1347        <entry><literal>120</literal></entry>
1348       </row>
1349
1350       <row>
1351        <entry>
1352         <indexterm>
1353          <primary>btrim</primary>
1354         </indexterm>
1355         <literal><function>btrim(<parameter>string</parameter> <type>text</type>
1356         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1357        </entry>
1358        <entry><type>text</type></entry>
1359        <entry>
1360         Remove the longest string consisting only of characters
1361         in <parameter>characters</parameter> (a space by default)
1362         from the start and end of <parameter>string</parameter>
1363        </entry>
1364        <entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
1365        <entry><literal>trim</literal></entry>
1366       </row>
1367
1368       <row>
1369        <entry>
1370         <indexterm>
1371          <primary>chr</primary>
1372         </indexterm>
1373         <literal><function>chr(<type>int</type>)</function></literal>
1374        </entry>
1375        <entry><type>text</type></entry>
1376        <entry>
1377         Character with the given code. For <acronym>UTF8</acronym> the
1378         argument is treated as a Unicode code point. For other multibyte
1379         encodings the argument must designate an
1380         <acronym>ASCII</acronym> character.  The NULL (0) character is not
1381         allowed because text data types cannot store such bytes.
1382        </entry>
1383        <entry><literal>chr(65)</literal></entry>
1384        <entry><literal>A</literal></entry>
1385       </row>
1386
1387       <row>
1388        <entry>
1389         <indexterm>
1390          <primary>concat</primary>
1391         </indexterm>
1392         <literal><function>concat(<parameter>str</parameter> <type>"any"</type>
1393          [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
1394        </entry>
1395        <entry><type>text</type></entry>
1396        <entry>
1397         Concatenate the text representations of all the arguments.
1398         NULL arguments are ignored.
1399        </entry>
1400        <entry><literal>concat('abcde', 2, NULL, 22)</literal></entry>
1401        <entry><literal>abcde222</literal></entry>
1402       </row>
1403
1404       <row>
1405        <entry>
1406         <indexterm>
1407          <primary>concat_ws</primary>
1408         </indexterm>
1409         <literal><function>concat_ws(<parameter>sep</parameter> <type>text</type>,
1410         <parameter>str</parameter> <type>"any"</type>
1411         [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
1412        </entry>
1413        <entry><type>text</type></entry>
1414        <entry>
1415         Concatenate all but the first argument with separators. The first
1416         argument is used as the separator string. NULL arguments are ignored.
1417        </entry>
1418        <entry><literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal></entry>
1419        <entry><literal>abcde,2,22</literal></entry>
1420       </row>
1421
1422       <row>
1423        <entry>
1424         <indexterm>
1425          <primary>convert</primary>
1426         </indexterm>
1427         <literal><function>convert(<parameter>string</parameter> <type>bytea</type>,
1428         <parameter>src_encoding</parameter> <type>name</type>,
1429         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1430        </entry>
1431        <entry><type>bytea</type></entry>
1432        <entry>
1433         Convert string to <parameter>dest_encoding</parameter>.  The
1434         original encoding is specified by
1435         <parameter>src_encoding</parameter>. The
1436         <parameter>string</parameter> must be valid in this encoding.
1437         Conversions can be defined by <command>CREATE CONVERSION</command>.
1438         Also there are some predefined conversions. See <xref
1439         linkend="conversion-names"> for available conversions.
1440        </entry>
1441        <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1442        <entry><literal>text_in_utf8</literal> represented in Latin-1
1443        encoding (ISO 8859-1)</entry>
1444       </row>
1445
1446       <row>
1447        <entry>
1448         <indexterm>
1449          <primary>convert_from</primary>
1450         </indexterm>
1451         <literal><function>convert_from(<parameter>string</parameter> <type>bytea</type>,
1452         <parameter>src_encoding</parameter> <type>name</type>)</function></literal>
1453        </entry>
1454        <entry><type>text</type></entry>
1455        <entry>
1456         Convert string to the database encoding.  The original encoding
1457         is specified by <parameter>src_encoding</parameter>. The
1458         <parameter>string</parameter> must be valid in this encoding.
1459        </entry>
1460        <entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
1461        <entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
1462       </row>
1463
1464       <row>
1465        <entry>
1466         <indexterm>
1467          <primary>convert_to</primary>
1468         </indexterm>
1469         <literal><function>convert_to(<parameter>string</parameter> <type>text</type>,
1470         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1471        </entry>
1472        <entry><type>bytea</type></entry>
1473        <entry>
1474         Convert string to <parameter>dest_encoding</parameter>.
1475        </entry>
1476        <entry><literal>convert_to('some text', 'UTF8')</literal></entry>
1477        <entry><literal>some text</literal> represented in the UTF8 encoding</entry>
1478       </row>
1479
1480       <row>
1481        <entry>
1482         <indexterm>
1483          <primary>decode</primary>
1484         </indexterm>
1485         <literal><function>decode(<parameter>string</parameter> <type>text</type>,
1486         <parameter>format</parameter> <type>text</type>)</function></literal>
1487        </entry>
1488        <entry><type>bytea</type></entry>
1489        <entry>
1490         Decode binary data from textual representation in <parameter>string</>.
1491         Options for <parameter>format</> are same as in <function>encode</>.
1492        </entry>
1493        <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
1494        <entry><literal>\x3132330001</literal></entry>
1495       </row>
1496
1497       <row>
1498        <entry>
1499         <indexterm>
1500          <primary>encode</primary>
1501         </indexterm>
1502         <literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
1503         <parameter>format</parameter> <type>text</type>)</function></literal>
1504        </entry>
1505        <entry><type>text</type></entry>
1506        <entry>
1507         Encode binary data into a textual representation.  Supported
1508         formats are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
1509         <literal>escape</> converts zero bytes and high-bit-set bytes to
1510         octal sequences (<literal>\</><replaceable>nnn</>) and
1511         doubles backslashes.
1512        </entry>
1513        <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1514        <entry><literal>MTIzAAE=</literal></entry>
1515       </row>
1516
1517       <row>
1518        <entry id="format">
1519         <indexterm>
1520          <primary>format</primary>
1521         </indexterm>
1522         <literal><function>format</function>(<parameter>formatstr</parameter> <type>text</type>
1523         [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ])</literal>
1524        </entry>
1525        <entry><type>text</type></entry>
1526        <entry>
1527          Format arguments according to a format string.
1528          This function is similar to the C function <function>sprintf</>.
1529          See <xref linkend="functions-string-format">.
1530        </entry>
1531        <entry><literal>format('Hello %s, %1$s', 'World')</literal></entry>
1532        <entry><literal>Hello World, World</literal></entry>
1533       </row>
1534
1535       <row>
1536        <entry>
1537         <indexterm>
1538          <primary>initcap</primary>
1539         </indexterm>
1540         <literal><function>initcap(<parameter>string</parameter>)</function></literal>
1541        </entry>
1542        <entry><type>text</type></entry>
1543        <entry>
1544         Convert the first letter of each word to upper case and the
1545         rest to lower case. Words are sequences of alphanumeric
1546         characters separated by non-alphanumeric characters.
1547        </entry>
1548        <entry><literal>initcap('hi THOMAS')</literal></entry>
1549        <entry><literal>Hi Thomas</literal></entry>
1550       </row>
1551
1552       <row>
1553        <entry>
1554         <indexterm>
1555          <primary>left</primary>
1556         </indexterm>
1557         <literal><function>left(<parameter>str</parameter> <type>text</type>,
1558         <parameter>n</parameter> <type>int</type>)</function></literal>
1559        </entry>
1560        <entry><type>text</type></entry>
1561        <entry>
1562         Return first <replaceable>n</> characters in the string. When <replaceable>n</>
1563         is negative, return all but last |<replaceable>n</>| characters.
1564         </entry>
1565        <entry><literal>left('abcde', 2)</literal></entry>
1566        <entry><literal>ab</literal></entry>
1567       </row>
1568
1569       <row>
1570        <entry>
1571         <indexterm>
1572          <primary>length</primary>
1573         </indexterm>
1574         <literal><function>length(<parameter>string</parameter>)</function></literal>
1575        </entry>
1576        <entry><type>int</type></entry>
1577        <entry>
1578         Number of characters in <parameter>string</parameter>
1579        </entry>
1580        <entry><literal>length('jose')</literal></entry>
1581        <entry><literal>4</literal></entry>
1582       </row>
1583
1584       <row>
1585        <entry><literal><function>length(<parameter>string</parameter> <type>bytea</type>,
1586         <parameter>encoding</parameter> <type>name</type> )</function></literal></entry>
1587        <entry><type>int</type></entry>
1588        <entry>
1589         Number of characters in <parameter>string</parameter> in the given
1590         <parameter>encoding</parameter>. The <parameter>string</parameter>
1591         must be valid in this encoding.
1592        </entry>
1593        <entry><literal>length('jose', 'UTF8')</literal></entry>
1594        <entry><literal>4</literal></entry>
1595       </row>
1596
1597       <row>
1598        <entry>
1599         <indexterm>
1600          <primary>lpad</primary>
1601         </indexterm>
1602         <literal><function>lpad(<parameter>string</parameter> <type>text</type>,
1603         <parameter>length</parameter> <type>int</type>
1604         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1605        </entry>
1606        <entry><type>text</type></entry>
1607        <entry>
1608         Fill up the <parameter>string</parameter> to length
1609         <parameter>length</parameter> by prepending the characters
1610         <parameter>fill</parameter> (a space by default).  If the
1611         <parameter>string</parameter> is already longer than
1612         <parameter>length</parameter> then it is truncated (on the
1613         right).
1614        </entry>
1615        <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1616        <entry><literal>xyxhi</literal></entry>
1617       </row>
1618
1619       <row>
1620        <entry>
1621         <indexterm>
1622          <primary>ltrim</primary>
1623         </indexterm>
1624         <literal><function>ltrim(<parameter>string</parameter> <type>text</type>
1625         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1626        </entry>
1627        <entry><type>text</type></entry>
1628        <entry>
1629         Remove the longest string containing only characters from
1630         <parameter>characters</parameter> (a space by default) from the start of
1631         <parameter>string</parameter>
1632        </entry>
1633        <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
1634        <entry><literal>trim</literal></entry>
1635       </row>
1636
1637       <row>
1638        <entry>
1639         <indexterm>
1640          <primary>md5</primary>
1641         </indexterm>
1642         <literal><function>md5(<parameter>string</parameter>)</function></literal>
1643        </entry>
1644        <entry><type>text</type></entry>
1645        <entry>
1646         Calculates the MD5 hash of <parameter>string</parameter>,
1647         returning the result in hexadecimal
1648        </entry>
1649        <entry><literal>md5('abc')</literal></entry>
1650        <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1651       </row>
1652
1653       <row>
1654        <entry>
1655         <indexterm>
1656          <primary>pg_client_encoding</primary>
1657         </indexterm>
1658         <literal><function>pg_client_encoding()</function></literal>
1659        </entry>
1660        <entry><type>name</type></entry>
1661        <entry>
1662         Current client encoding name
1663        </entry>
1664        <entry><literal>pg_client_encoding()</literal></entry>
1665        <entry><literal>SQL_ASCII</literal></entry>
1666       </row>
1667
1668       <row>
1669        <entry>
1670         <indexterm>
1671          <primary>quote_ident</primary>
1672         </indexterm>
1673         <literal><function>quote_ident(<parameter>string</parameter> <type>text</type>)</function></literal>
1674        </entry>
1675        <entry><type>text</type></entry>
1676        <entry>
1677         Return the given string suitably quoted to be used as an identifier
1678         in an <acronym>SQL</acronym> statement string.
1679         Quotes are added only if necessary (i.e., if the string contains
1680         non-identifier characters or would be case-folded).
1681         Embedded quotes are properly doubled.
1682         See also <xref linkend="plpgsql-quote-literal-example">.
1683        </entry>
1684        <entry><literal>quote_ident('Foo bar')</literal></entry>
1685        <entry><literal>"Foo bar"</literal></entry>
1686       </row>
1687
1688       <row>
1689        <entry>
1690         <indexterm>
1691          <primary>quote_literal</primary>
1692         </indexterm>
1693         <literal><function>quote_literal(<parameter>string</parameter> <type>text</type>)</function></literal>
1694        </entry>
1695        <entry><type>text</type></entry>
1696        <entry>
1697         Return the given string suitably quoted to be used as a string literal
1698         in an <acronym>SQL</acronym> statement string.
1699         Embedded single-quotes and backslashes are properly doubled.
1700         Note that <function>quote_literal</function> returns null on null
1701         input; if the argument might be null,
1702         <function>quote_nullable</function> is often more suitable.
1703         See also <xref linkend="plpgsql-quote-literal-example">.
1704        </entry>
1705        <entry><literal>quote_literal(E'O\'Reilly')</literal></entry>
1706        <entry><literal>'O''Reilly'</literal></entry>
1707       </row>
1708
1709       <row>
1710        <entry><literal><function>quote_literal(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1711        <entry><type>text</type></entry>
1712        <entry>
1713         Coerce the given value to text and then quote it as a literal.
1714         Embedded single-quotes and backslashes are properly doubled.
1715        </entry>
1716        <entry><literal>quote_literal(42.5)</literal></entry>
1717        <entry><literal>'42.5'</literal></entry>
1718       </row>
1719
1720       <row>
1721        <entry>
1722         <indexterm>
1723          <primary>quote_nullable</primary>
1724         </indexterm>
1725         <literal><function>quote_nullable(<parameter>string</parameter> <type>text</type>)</function></literal>
1726        </entry>
1727        <entry><type>text</type></entry>
1728        <entry>
1729         Return the given string suitably quoted to be used as a string literal
1730         in an <acronym>SQL</acronym> statement string; or, if the argument
1731         is null, return <literal>NULL</>.
1732         Embedded single-quotes and backslashes are properly doubled.
1733         See also <xref linkend="plpgsql-quote-literal-example">.
1734        </entry>
1735        <entry><literal>quote_nullable(NULL)</literal></entry>
1736        <entry><literal>NULL</literal></entry>
1737       </row>
1738
1739       <row>
1740        <entry><literal><function>quote_nullable(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1741        <entry><type>text</type></entry>
1742        <entry>
1743         Coerce the given value to text and then quote it as a literal;
1744         or, if the argument is null, return <literal>NULL</>.
1745         Embedded single-quotes and backslashes are properly doubled.
1746        </entry>
1747        <entry><literal>quote_nullable(42.5)</literal></entry>
1748        <entry><literal>'42.5'</literal></entry>
1749       </row>
1750
1751       <row>
1752        <entry>
1753         <indexterm>
1754          <primary>regexp_matches</primary>
1755         </indexterm>
1756         <literal><function>regexp_matches(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
1757        </entry>
1758        <entry><type>setof text[]</type></entry>
1759        <entry>
1760         Return all captured substrings resulting from matching a POSIX regular
1761         expression against the <parameter>string</parameter>. See
1762         <xref linkend="functions-posix-regexp"> for more information.
1763        </entry>
1764        <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
1765        <entry><literal>{bar,beque}</literal></entry>
1766       </row>
1767
1768       <row>
1769        <entry>
1770         <indexterm>
1771          <primary>regexp_replace</primary>
1772         </indexterm>
1773         <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>
1774        </entry>
1775        <entry><type>text</type></entry>
1776        <entry>
1777         Replace substring(s) matching a POSIX regular expression. See
1778         <xref linkend="functions-posix-regexp"> for more information.
1779        </entry>
1780        <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
1781        <entry><literal>ThM</literal></entry>
1782       </row>
1783
1784       <row>
1785        <entry>
1786         <indexterm>
1787          <primary>regexp_split_to_array</primary>
1788         </indexterm>
1789         <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>
1790        </entry>
1791        <entry><type>text[]</type></entry>
1792        <entry>
1793         Split <parameter>string</parameter> using a POSIX regular expression as
1794         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1795         information.
1796        </entry>
1797        <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
1798        <entry><literal>{hello,world}</literal></entry>
1799       </row>
1800
1801       <row>
1802        <entry>
1803         <indexterm>
1804          <primary>regexp_split_to_table</primary>
1805         </indexterm>
1806         <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>
1807        </entry>
1808        <entry><type>setof text</type></entry>
1809        <entry>
1810         Split <parameter>string</parameter> using a POSIX regular expression as
1811         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1812         information.
1813        </entry>
1814        <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
1815        <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
1816       </row>
1817
1818       <row>
1819        <entry>
1820         <indexterm>
1821          <primary>repeat</primary>
1822         </indexterm>
1823         <literal><function>repeat(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</function></literal>
1824        </entry>
1825        <entry><type>text</type></entry>
1826        <entry>Repeat <parameter>string</parameter> the specified
1827        <parameter>number</parameter> of times</entry>
1828        <entry><literal>repeat('Pg', 4)</literal></entry>
1829        <entry><literal>PgPgPgPg</literal></entry>
1830       </row>
1831
1832       <row>
1833        <entry>
1834         <indexterm>
1835          <primary>replace</primary>
1836         </indexterm>
1837         <literal><function>replace(<parameter>string</parameter> <type>text</type>,
1838         <parameter>from</parameter> <type>text</type>,
1839         <parameter>to</parameter> <type>text</type>)</function></literal>
1840        </entry>
1841        <entry><type>text</type></entry>
1842        <entry>Replace all occurrences in <parameter>string</parameter> of substring
1843         <parameter>from</parameter> with substring <parameter>to</parameter>
1844        </entry>
1845        <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
1846        <entry><literal>abXXefabXXef</literal></entry>
1847       </row>
1848
1849       <row>
1850        <entry>
1851         <indexterm>
1852          <primary>reverse</primary>
1853         </indexterm>
1854         <literal><function>reverse(<parameter>str</parameter>)</function></literal>
1855        </entry>
1856        <entry><type>text</type></entry>
1857        <entry>
1858         Return reversed string.
1859        </entry>
1860        <entry><literal>reverse('abcde')</literal></entry>
1861        <entry><literal>edcba</literal></entry>
1862       </row>
1863
1864       <row>
1865        <entry>
1866         <indexterm>
1867          <primary>right</primary>
1868         </indexterm>
1869         <literal><function>right(<parameter>str</parameter> <type>text</type>,
1870          <parameter>n</parameter> <type>int</type>)</function></literal>
1871        </entry>
1872        <entry><type>text</type></entry>
1873        <entry>
1874         Return last <replaceable>n</> characters in the string. When <replaceable>n</>
1875         is negative, return all but first |<replaceable>n</>| characters.
1876        </entry>
1877        <entry><literal>right('abcde', 2)</literal></entry>
1878        <entry><literal>de</literal></entry>
1879       </row>
1880
1881       <row>
1882        <entry>
1883         <indexterm>
1884          <primary>rpad</primary>
1885         </indexterm>
1886         <literal><function>rpad(<parameter>string</parameter> <type>text</type>,
1887         <parameter>length</parameter> <type>int</type>
1888         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1889        </entry>
1890        <entry><type>text</type></entry>
1891        <entry>
1892         Fill up the <parameter>string</parameter> to length
1893         <parameter>length</parameter> by appending the characters
1894         <parameter>fill</parameter> (a space by default).  If the
1895         <parameter>string</parameter> is already longer than
1896         <parameter>length</parameter> then it is truncated.
1897        </entry>
1898        <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
1899        <entry><literal>hixyx</literal></entry>
1900       </row>
1901
1902       <row>
1903        <entry>
1904         <indexterm>
1905          <primary>rtrim</primary>
1906         </indexterm>
1907         <literal><function>rtrim(<parameter>string</parameter> <type>text</type>
1908          <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1909        </entry>
1910        <entry><type>text</type></entry>
1911        <entry>
1912         Remove the longest string containing only characters from
1913         <parameter>characters</parameter> (a space by default) from the end of
1914         <parameter>string</parameter>
1915        </entry>
1916        <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
1917        <entry><literal>trim</literal></entry>
1918       </row>
1919
1920       <row>
1921        <entry>
1922         <indexterm>
1923          <primary>split_part</primary>
1924         </indexterm>
1925         <literal><function>split_part(<parameter>string</parameter> <type>text</type>,
1926         <parameter>delimiter</parameter> <type>text</type>,
1927         <parameter>field</parameter> <type>int</type>)</function></literal>
1928        </entry>
1929        <entry><type>text</type></entry>
1930        <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1931         and return the given field (counting from one)
1932        </entry>
1933        <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
1934        <entry><literal>def</literal></entry>
1935       </row>
1936
1937       <row>
1938        <entry>
1939         <indexterm>
1940          <primary>strpos</primary>
1941         </indexterm>
1942         <literal><function>strpos(<parameter>string</parameter>, <parameter>substring</parameter>)</function></literal>
1943        </entry>
1944        <entry><type>int</type></entry>
1945        <entry>
1946         Location of specified substring (same as
1947         <literal>position(<parameter>substring</parameter> in
1948          <parameter>string</parameter>)</literal>, but note the reversed
1949         argument order)
1950        </entry>
1951        <entry><literal>strpos('high', 'ig')</literal></entry>
1952        <entry><literal>2</literal></entry>
1953       </row>
1954
1955       <row>
1956        <entry>
1957         <indexterm>
1958          <primary>substr</primary>
1959         </indexterm>
1960         <literal><function>substr(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</function></literal>
1961        </entry>
1962        <entry><type>text</type></entry>
1963        <entry>
1964         Extract substring (same as
1965         <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
1966        </entry>
1967        <entry><literal>substr('alphabet', 3, 2)</literal></entry>
1968        <entry><literal>ph</literal></entry>
1969       </row>
1970
1971       <row>
1972        <entry>
1973         <indexterm>
1974          <primary>to_ascii</primary>
1975         </indexterm>
1976         <literal><function>to_ascii(<parameter>string</parameter> <type>text</type>
1977         <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</function></literal>
1978        </entry>
1979        <entry><type>text</type></entry>
1980        <entry>
1981        Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
1982        (only supports conversion from  <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
1983        and <literal>WIN1250</> encodings)
1984        </entry>
1985        <entry><literal>to_ascii('Karel')</literal></entry>
1986        <entry><literal>Karel</literal></entry>
1987       </row>
1988
1989       <row>
1990        <entry>
1991         <indexterm>
1992          <primary>to_hex</primary>
1993         </indexterm>
1994         <literal><function>to_hex(<parameter>number</parameter> <type>int</type>
1995         or <type>bigint</type>)</function></literal>
1996        </entry>
1997        <entry><type>text</type></entry>
1998        <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
1999         representation
2000        </entry>
2001        <entry><literal>to_hex(2147483647)</literal></entry>
2002        <entry><literal>7fffffff</literal></entry>
2003       </row>
2004
2005       <row>
2006        <entry>
2007         <indexterm>
2008          <primary>translate</primary>
2009         </indexterm>
2010         <literal><function>translate(<parameter>string</parameter> <type>text</type>,
2011         <parameter>from</parameter> <type>text</type>,
2012         <parameter>to</parameter> <type>text</type>)</function></literal>
2013        </entry>
2014        <entry><type>text</type></entry>
2015        <entry>
2016         Any character in <parameter>string</parameter> that matches a
2017         character in the <parameter>from</parameter> set is replaced by
2018         the corresponding character in the <parameter>to</parameter>
2019         set. If <parameter>from</parameter> is longer than
2020         <parameter>to</parameter>, occurrences of the extra characters in
2021         <parameter>from</parameter> are removed.
2022        </entry>
2023        <entry><literal>translate('12345', '143', 'ax')</literal></entry>
2024        <entry><literal>a2x5</literal></entry>
2025       </row>
2026
2027      </tbody>
2028     </tgroup>
2029    </table>
2030
2031    <para>
2032     The <function>concat</function>, <function>concat_ws</function> and
2033     <function>format</function> functions are variadic, so it is possible to
2034     pass the values to be concatenated or formatted as an array marked with
2035     the <literal>VARIADIC</literal> keyword (see <xref
2036     linkend="xfunc-sql-variadic-functions">).  The array's elements are
2037     treated as if they were separate ordinary arguments to the function.
2038     If the variadic array argument is NULL, <function>concat</function>
2039     and <function>concat_ws</function> return NULL, but
2040     <function>format</function> treats a NULL as a zero-element array.
2041    </para>
2042
2043    <para>
2044    See also the aggregate function <function>string_agg</function> in
2045    <xref linkend="functions-aggregate">.
2046    </para>
2047
2048    <table id="conversion-names">
2049     <title>Built-in Conversions</title>
2050     <tgroup cols="3">
2051      <thead>
2052       <row>
2053        <entry>Conversion Name
2054         <footnote>
2055          <para>
2056           The conversion names follow a standard naming scheme: The
2057           official name of the source encoding with all
2058           non-alphanumeric characters replaced by underscores, followed
2059           by <literal>_to_</literal>, followed by the similarly processed
2060           destination encoding name. Therefore, the names might deviate
2061           from the customary encoding names.
2062          </para>
2063         </footnote>
2064        </entry>
2065        <entry>Source Encoding</entry>
2066        <entry>Destination Encoding</entry>
2067       </row>
2068      </thead>
2069
2070      <tbody>
2071       <row>
2072        <entry><literal>ascii_to_mic</literal></entry>
2073        <entry><literal>SQL_ASCII</literal></entry>
2074        <entry><literal>MULE_INTERNAL</literal></entry>
2075       </row>
2076
2077       <row>
2078        <entry><literal>ascii_to_utf8</literal></entry>
2079        <entry><literal>SQL_ASCII</literal></entry>
2080        <entry><literal>UTF8</literal></entry>
2081       </row>
2082
2083       <row>
2084        <entry><literal>big5_to_euc_tw</literal></entry>
2085        <entry><literal>BIG5</literal></entry>
2086        <entry><literal>EUC_TW</literal></entry>
2087       </row>
2088
2089       <row>
2090        <entry><literal>big5_to_mic</literal></entry>
2091        <entry><literal>BIG5</literal></entry>
2092        <entry><literal>MULE_INTERNAL</literal></entry>
2093       </row>
2094
2095       <row>
2096        <entry><literal>big5_to_utf8</literal></entry>
2097        <entry><literal>BIG5</literal></entry>
2098        <entry><literal>UTF8</literal></entry>
2099       </row>
2100
2101       <row>
2102        <entry><literal>euc_cn_to_mic</literal></entry>
2103        <entry><literal>EUC_CN</literal></entry>
2104        <entry><literal>MULE_INTERNAL</literal></entry>
2105       </row>
2106
2107       <row>
2108        <entry><literal>euc_cn_to_utf8</literal></entry>
2109        <entry><literal>EUC_CN</literal></entry>
2110        <entry><literal>UTF8</literal></entry>
2111       </row>
2112
2113       <row>
2114        <entry><literal>euc_jp_to_mic</literal></entry>
2115        <entry><literal>EUC_JP</literal></entry>
2116        <entry><literal>MULE_INTERNAL</literal></entry>
2117       </row>
2118
2119       <row>
2120        <entry><literal>euc_jp_to_sjis</literal></entry>
2121        <entry><literal>EUC_JP</literal></entry>
2122        <entry><literal>SJIS</literal></entry>
2123       </row>
2124
2125       <row>
2126        <entry><literal>euc_jp_to_utf8</literal></entry>
2127        <entry><literal>EUC_JP</literal></entry>
2128        <entry><literal>UTF8</literal></entry>
2129       </row>
2130
2131       <row>
2132        <entry><literal>euc_kr_to_mic</literal></entry>
2133        <entry><literal>EUC_KR</literal></entry>
2134        <entry><literal>MULE_INTERNAL</literal></entry>
2135       </row>
2136
2137       <row>
2138        <entry><literal>euc_kr_to_utf8</literal></entry>
2139        <entry><literal>EUC_KR</literal></entry>
2140        <entry><literal>UTF8</literal></entry>
2141       </row>
2142
2143       <row>
2144        <entry><literal>euc_tw_to_big5</literal></entry>
2145        <entry><literal>EUC_TW</literal></entry>
2146        <entry><literal>BIG5</literal></entry>
2147       </row>
2148
2149       <row>
2150        <entry><literal>euc_tw_to_mic</literal></entry>
2151        <entry><literal>EUC_TW</literal></entry>
2152        <entry><literal>MULE_INTERNAL</literal></entry>
2153       </row>
2154
2155       <row>
2156        <entry><literal>euc_tw_to_utf8</literal></entry>
2157        <entry><literal>EUC_TW</literal></entry>
2158        <entry><literal>UTF8</literal></entry>
2159       </row>
2160
2161       <row>
2162        <entry><literal>gb18030_to_utf8</literal></entry>
2163        <entry><literal>GB18030</literal></entry>
2164        <entry><literal>UTF8</literal></entry>
2165       </row>
2166
2167       <row>
2168        <entry><literal>gbk_to_utf8</literal></entry>
2169        <entry><literal>GBK</literal></entry>
2170        <entry><literal>UTF8</literal></entry>
2171       </row>
2172
2173       <row>
2174        <entry><literal>iso_8859_10_to_utf8</literal></entry>
2175        <entry><literal>LATIN6</literal></entry>
2176        <entry><literal>UTF8</literal></entry>
2177       </row>
2178
2179       <row>
2180        <entry><literal>iso_8859_13_to_utf8</literal></entry>
2181        <entry><literal>LATIN7</literal></entry>
2182        <entry><literal>UTF8</literal></entry>
2183       </row>
2184
2185       <row>
2186        <entry><literal>iso_8859_14_to_utf8</literal></entry>
2187        <entry><literal>LATIN8</literal></entry>
2188        <entry><literal>UTF8</literal></entry>
2189       </row>
2190
2191       <row>
2192        <entry><literal>iso_8859_15_to_utf8</literal></entry>
2193        <entry><literal>LATIN9</literal></entry>
2194        <entry><literal>UTF8</literal></entry>
2195       </row>
2196
2197       <row>
2198        <entry><literal>iso_8859_16_to_utf8</literal></entry>
2199        <entry><literal>LATIN10</literal></entry>
2200        <entry><literal>UTF8</literal></entry>
2201       </row>
2202
2203       <row>
2204        <entry><literal>iso_8859_1_to_mic</literal></entry>
2205        <entry><literal>LATIN1</literal></entry>
2206        <entry><literal>MULE_INTERNAL</literal></entry>
2207       </row>
2208
2209       <row>
2210        <entry><literal>iso_8859_1_to_utf8</literal></entry>
2211        <entry><literal>LATIN1</literal></entry>
2212        <entry><literal>UTF8</literal></entry>
2213       </row>
2214
2215       <row>
2216        <entry><literal>iso_8859_2_to_mic</literal></entry>
2217        <entry><literal>LATIN2</literal></entry>
2218        <entry><literal>MULE_INTERNAL</literal></entry>
2219       </row>
2220
2221       <row>
2222        <entry><literal>iso_8859_2_to_utf8</literal></entry>
2223        <entry><literal>LATIN2</literal></entry>
2224        <entry><literal>UTF8</literal></entry>
2225       </row>
2226
2227       <row>
2228        <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
2229        <entry><literal>LATIN2</literal></entry>
2230        <entry><literal>WIN1250</literal></entry>
2231       </row>
2232
2233       <row>
2234        <entry><literal>iso_8859_3_to_mic</literal></entry>
2235        <entry><literal>LATIN3</literal></entry>
2236        <entry><literal>MULE_INTERNAL</literal></entry>
2237       </row>
2238
2239       <row>
2240        <entry><literal>iso_8859_3_to_utf8</literal></entry>
2241        <entry><literal>LATIN3</literal></entry>
2242        <entry><literal>UTF8</literal></entry>
2243       </row>
2244
2245       <row>
2246        <entry><literal>iso_8859_4_to_mic</literal></entry>
2247        <entry><literal>LATIN4</literal></entry>
2248        <entry><literal>MULE_INTERNAL</literal></entry>
2249       </row>
2250
2251       <row>
2252        <entry><literal>iso_8859_4_to_utf8</literal></entry>
2253        <entry><literal>LATIN4</literal></entry>
2254        <entry><literal>UTF8</literal></entry>
2255       </row>
2256
2257       <row>
2258        <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
2259        <entry><literal>ISO_8859_5</literal></entry>
2260        <entry><literal>KOI8R</literal></entry>
2261       </row>
2262
2263       <row>
2264        <entry><literal>iso_8859_5_to_mic</literal></entry>
2265        <entry><literal>ISO_8859_5</literal></entry>
2266        <entry><literal>MULE_INTERNAL</literal></entry>
2267       </row>
2268
2269       <row>
2270        <entry><literal>iso_8859_5_to_utf8</literal></entry>
2271        <entry><literal>ISO_8859_5</literal></entry>
2272        <entry><literal>UTF8</literal></entry>
2273       </row>
2274
2275       <row>
2276        <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
2277        <entry><literal>ISO_8859_5</literal></entry>
2278        <entry><literal>WIN1251</literal></entry>
2279       </row>
2280
2281       <row>
2282        <entry><literal>iso_8859_5_to_windows_866</literal></entry>
2283        <entry><literal>ISO_8859_5</literal></entry>
2284        <entry><literal>WIN866</literal></entry>
2285       </row>
2286
2287       <row>
2288        <entry><literal>iso_8859_6_to_utf8</literal></entry>
2289        <entry><literal>ISO_8859_6</literal></entry>
2290        <entry><literal>UTF8</literal></entry>
2291       </row>
2292
2293       <row>
2294        <entry><literal>iso_8859_7_to_utf8</literal></entry>
2295        <entry><literal>ISO_8859_7</literal></entry>
2296        <entry><literal>UTF8</literal></entry>
2297       </row>
2298
2299       <row>
2300        <entry><literal>iso_8859_8_to_utf8</literal></entry>
2301        <entry><literal>ISO_8859_8</literal></entry>
2302        <entry><literal>UTF8</literal></entry>
2303       </row>
2304
2305       <row>
2306        <entry><literal>iso_8859_9_to_utf8</literal></entry>
2307        <entry><literal>LATIN5</literal></entry>
2308        <entry><literal>UTF8</literal></entry>
2309       </row>
2310
2311       <row>
2312        <entry><literal>johab_to_utf8</literal></entry>
2313        <entry><literal>JOHAB</literal></entry>
2314        <entry><literal>UTF8</literal></entry>
2315       </row>
2316
2317       <row>
2318        <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
2319        <entry><literal>KOI8R</literal></entry>
2320        <entry><literal>ISO_8859_5</literal></entry>
2321       </row>
2322
2323       <row>
2324        <entry><literal>koi8_r_to_mic</literal></entry>
2325        <entry><literal>KOI8R</literal></entry>
2326        <entry><literal>MULE_INTERNAL</literal></entry>
2327       </row>
2328
2329       <row>
2330        <entry><literal>koi8_r_to_utf8</literal></entry>
2331        <entry><literal>KOI8R</literal></entry>
2332        <entry><literal>UTF8</literal></entry>
2333       </row>
2334
2335       <row>
2336        <entry><literal>koi8_r_to_windows_1251</literal></entry>
2337        <entry><literal>KOI8R</literal></entry>
2338        <entry><literal>WIN1251</literal></entry>
2339       </row>
2340
2341       <row>
2342        <entry><literal>koi8_r_to_windows_866</literal></entry>
2343        <entry><literal>KOI8R</literal></entry>
2344        <entry><literal>WIN866</literal></entry>
2345       </row>
2346
2347       <row>
2348        <entry><literal>koi8_u_to_utf8</literal></entry>
2349        <entry><literal>KOI8U</literal></entry>
2350        <entry><literal>UTF8</literal></entry>
2351       </row>
2352
2353       <row>
2354        <entry><literal>mic_to_ascii</literal></entry>
2355        <entry><literal>MULE_INTERNAL</literal></entry>
2356        <entry><literal>SQL_ASCII</literal></entry>
2357       </row>
2358
2359       <row>
2360        <entry><literal>mic_to_big5</literal></entry>
2361        <entry><literal>MULE_INTERNAL</literal></entry>
2362        <entry><literal>BIG5</literal></entry>
2363       </row>
2364
2365       <row>
2366        <entry><literal>mic_to_euc_cn</literal></entry>
2367        <entry><literal>MULE_INTERNAL</literal></entry>
2368        <entry><literal>EUC_CN</literal></entry>
2369       </row>
2370
2371       <row>
2372        <entry><literal>mic_to_euc_jp</literal></entry>
2373        <entry><literal>MULE_INTERNAL</literal></entry>
2374        <entry><literal>EUC_JP</literal></entry>
2375       </row>
2376
2377       <row>
2378        <entry><literal>mic_to_euc_kr</literal></entry>
2379        <entry><literal>MULE_INTERNAL</literal></entry>
2380        <entry><literal>EUC_KR</literal></entry>
2381       </row>
2382
2383       <row>
2384        <entry><literal>mic_to_euc_tw</literal></entry>
2385        <entry><literal>MULE_INTERNAL</literal></entry>
2386        <entry><literal>EUC_TW</literal></entry>
2387       </row>
2388
2389       <row>
2390        <entry><literal>mic_to_iso_8859_1</literal></entry>
2391        <entry><literal>MULE_INTERNAL</literal></entry>
2392        <entry><literal>LATIN1</literal></entry>
2393       </row>
2394
2395       <row>
2396        <entry><literal>mic_to_iso_8859_2</literal></entry>
2397        <entry><literal>MULE_INTERNAL</literal></entry>
2398        <entry><literal>LATIN2</literal></entry>
2399       </row>
2400
2401       <row>
2402        <entry><literal>mic_to_iso_8859_3</literal></entry>
2403        <entry><literal>MULE_INTERNAL</literal></entry>
2404        <entry><literal>LATIN3</literal></entry>
2405       </row>
2406
2407       <row>
2408        <entry><literal>mic_to_iso_8859_4</literal></entry>
2409        <entry><literal>MULE_INTERNAL</literal></entry>
2410        <entry><literal>LATIN4</literal></entry>
2411       </row>
2412
2413       <row>
2414        <entry><literal>mic_to_iso_8859_5</literal></entry>
2415        <entry><literal>MULE_INTERNAL</literal></entry>
2416        <entry><literal>ISO_8859_5</literal></entry>
2417       </row>
2418
2419       <row>
2420        <entry><literal>mic_to_koi8_r</literal></entry>
2421        <entry><literal>MULE_INTERNAL</literal></entry>
2422        <entry><literal>KOI8R</literal></entry>
2423       </row>
2424
2425       <row>
2426        <entry><literal>mic_to_sjis</literal></entry>
2427        <entry><literal>MULE_INTERNAL</literal></entry>
2428        <entry><literal>SJIS</literal></entry>
2429       </row>
2430
2431       <row>
2432        <entry><literal>mic_to_windows_1250</literal></entry>
2433        <entry><literal>MULE_INTERNAL</literal></entry>
2434        <entry><literal>WIN1250</literal></entry>
2435       </row>
2436
2437       <row>
2438        <entry><literal>mic_to_windows_1251</literal></entry>
2439        <entry><literal>MULE_INTERNAL</literal></entry>
2440        <entry><literal>WIN1251</literal></entry>
2441       </row>
2442
2443       <row>
2444        <entry><literal>mic_to_windows_866</literal></entry>
2445        <entry><literal>MULE_INTERNAL</literal></entry>
2446        <entry><literal>WIN866</literal></entry>
2447       </row>
2448
2449       <row>
2450        <entry><literal>sjis_to_euc_jp</literal></entry>
2451        <entry><literal>SJIS</literal></entry>
2452        <entry><literal>EUC_JP</literal></entry>
2453       </row>
2454
2455       <row>
2456        <entry><literal>sjis_to_mic</literal></entry>
2457        <entry><literal>SJIS</literal></entry>
2458        <entry><literal>MULE_INTERNAL</literal></entry>
2459       </row>
2460
2461       <row>
2462        <entry><literal>sjis_to_utf8</literal></entry>
2463        <entry><literal>SJIS</literal></entry>
2464        <entry><literal>UTF8</literal></entry>
2465       </row>
2466
2467       <row>
2468        <entry><literal>tcvn_to_utf8</literal></entry>
2469        <entry><literal>WIN1258</literal></entry>
2470        <entry><literal>UTF8</literal></entry>
2471       </row>
2472
2473       <row>
2474        <entry><literal>uhc_to_utf8</literal></entry>
2475        <entry><literal>UHC</literal></entry>
2476        <entry><literal>UTF8</literal></entry>
2477       </row>
2478
2479       <row>
2480        <entry><literal>utf8_to_ascii</literal></entry>
2481        <entry><literal>UTF8</literal></entry>
2482        <entry><literal>SQL_ASCII</literal></entry>
2483       </row>
2484
2485       <row>
2486        <entry><literal>utf8_to_big5</literal></entry>
2487        <entry><literal>UTF8</literal></entry>
2488        <entry><literal>BIG5</literal></entry>
2489       </row>
2490
2491       <row>
2492        <entry><literal>utf8_to_euc_cn</literal></entry>
2493        <entry><literal>UTF8</literal></entry>
2494        <entry><literal>EUC_CN</literal></entry>
2495       </row>
2496
2497       <row>
2498        <entry><literal>utf8_to_euc_jp</literal></entry>
2499        <entry><literal>UTF8</literal></entry>
2500        <entry><literal>EUC_JP</literal></entry>
2501       </row>
2502
2503       <row>
2504        <entry><literal>utf8_to_euc_kr</literal></entry>
2505        <entry><literal>UTF8</literal></entry>
2506        <entry><literal>EUC_KR</literal></entry>
2507       </row>
2508
2509       <row>
2510        <entry><literal>utf8_to_euc_tw</literal></entry>
2511        <entry><literal>UTF8</literal></entry>
2512        <entry><literal>EUC_TW</literal></entry>
2513       </row>
2514
2515       <row>
2516        <entry><literal>utf8_to_gb18030</literal></entry>
2517        <entry><literal>UTF8</literal></entry>
2518        <entry><literal>GB18030</literal></entry>
2519       </row>
2520
2521       <row>
2522        <entry><literal>utf8_to_gbk</literal></entry>
2523        <entry><literal>UTF8</literal></entry>
2524        <entry><literal>GBK</literal></entry>
2525       </row>
2526
2527       <row>
2528        <entry><literal>utf8_to_iso_8859_1</literal></entry>
2529        <entry><literal>UTF8</literal></entry>
2530        <entry><literal>LATIN1</literal></entry>
2531       </row>
2532
2533       <row>
2534        <entry><literal>utf8_to_iso_8859_10</literal></entry>
2535        <entry><literal>UTF8</literal></entry>
2536        <entry><literal>LATIN6</literal></entry>
2537       </row>
2538
2539       <row>
2540        <entry><literal>utf8_to_iso_8859_13</literal></entry>
2541        <entry><literal>UTF8</literal></entry>
2542        <entry><literal>LATIN7</literal></entry>
2543       </row>
2544
2545       <row>
2546        <entry><literal>utf8_to_iso_8859_14</literal></entry>
2547        <entry><literal>UTF8</literal></entry>
2548        <entry><literal>LATIN8</literal></entry>
2549       </row>
2550
2551       <row>
2552        <entry><literal>utf8_to_iso_8859_15</literal></entry>
2553        <entry><literal>UTF8</literal></entry>
2554        <entry><literal>LATIN9</literal></entry>
2555       </row>
2556
2557       <row>
2558        <entry><literal>utf8_to_iso_8859_16</literal></entry>
2559        <entry><literal>UTF8</literal></entry>
2560        <entry><literal>LATIN10</literal></entry>
2561       </row>
2562
2563       <row>
2564        <entry><literal>utf8_to_iso_8859_2</literal></entry>
2565        <entry><literal>UTF8</literal></entry>
2566        <entry><literal>LATIN2</literal></entry>
2567       </row>
2568
2569       <row>
2570        <entry><literal>utf8_to_iso_8859_3</literal></entry>
2571        <entry><literal>UTF8</literal></entry>
2572        <entry><literal>LATIN3</literal></entry>
2573       </row>
2574
2575       <row>
2576        <entry><literal>utf8_to_iso_8859_4</literal></entry>
2577        <entry><literal>UTF8</literal></entry>
2578        <entry><literal>LATIN4</literal></entry>
2579       </row>
2580
2581       <row>
2582        <entry><literal>utf8_to_iso_8859_5</literal></entry>
2583        <entry><literal>UTF8</literal></entry>
2584        <entry><literal>ISO_8859_5</literal></entry>
2585       </row>
2586
2587       <row>
2588        <entry><literal>utf8_to_iso_8859_6</literal></entry>
2589        <entry><literal>UTF8</literal></entry>
2590        <entry><literal>ISO_8859_6</literal></entry>
2591       </row>
2592
2593       <row>
2594        <entry><literal>utf8_to_iso_8859_7</literal></entry>
2595        <entry><literal>UTF8</literal></entry>
2596        <entry><literal>ISO_8859_7</literal></entry>
2597       </row>
2598
2599       <row>
2600        <entry><literal>utf8_to_iso_8859_8</literal></entry>
2601        <entry><literal>UTF8</literal></entry>
2602        <entry><literal>ISO_8859_8</literal></entry>
2603       </row>
2604
2605       <row>
2606        <entry><literal>utf8_to_iso_8859_9</literal></entry>
2607        <entry><literal>UTF8</literal></entry>
2608        <entry><literal>LATIN5</literal></entry>
2609       </row>
2610
2611       <row>
2612        <entry><literal>utf8_to_johab</literal></entry>
2613        <entry><literal>UTF8</literal></entry>
2614        <entry><literal>JOHAB</literal></entry>
2615       </row>
2616
2617       <row>
2618        <entry><literal>utf8_to_koi8_r</literal></entry>
2619        <entry><literal>UTF8</literal></entry>
2620        <entry><literal>KOI8R</literal></entry>
2621       </row>
2622
2623       <row>
2624        <entry><literal>utf8_to_koi8_u</literal></entry>
2625        <entry><literal>UTF8</literal></entry>
2626        <entry><literal>KOI8U</literal></entry>
2627       </row>
2628
2629       <row>
2630        <entry><literal>utf8_to_sjis</literal></entry>
2631        <entry><literal>UTF8</literal></entry>
2632        <entry><literal>SJIS</literal></entry>
2633       </row>
2634
2635       <row>
2636        <entry><literal>utf8_to_tcvn</literal></entry>
2637        <entry><literal>UTF8</literal></entry>
2638        <entry><literal>WIN1258</literal></entry>
2639       </row>
2640
2641       <row>
2642        <entry><literal>utf8_to_uhc</literal></entry>
2643        <entry><literal>UTF8</literal></entry>
2644        <entry><literal>UHC</literal></entry>
2645       </row>
2646
2647       <row>
2648        <entry><literal>utf8_to_windows_1250</literal></entry>
2649        <entry><literal>UTF8</literal></entry>
2650        <entry><literal>WIN1250</literal></entry>
2651       </row>
2652
2653       <row>
2654        <entry><literal>utf8_to_windows_1251</literal></entry>
2655        <entry><literal>UTF8</literal></entry>
2656        <entry><literal>WIN1251</literal></entry>
2657       </row>
2658
2659       <row>
2660        <entry><literal>utf8_to_windows_1252</literal></entry>
2661        <entry><literal>UTF8</literal></entry>
2662        <entry><literal>WIN1252</literal></entry>
2663       </row>
2664
2665       <row>
2666        <entry><literal>utf8_to_windows_1253</literal></entry>
2667        <entry><literal>UTF8</literal></entry>
2668        <entry><literal>WIN1253</literal></entry>
2669       </row>
2670
2671       <row>
2672        <entry><literal>utf8_to_windows_1254</literal></entry>
2673        <entry><literal>UTF8</literal></entry>
2674        <entry><literal>WIN1254</literal></entry>
2675       </row>
2676
2677       <row>
2678        <entry><literal>utf8_to_windows_1255</literal></entry>
2679        <entry><literal>UTF8</literal></entry>
2680        <entry><literal>WIN1255</literal></entry>
2681       </row>
2682
2683       <row>
2684        <entry><literal>utf8_to_windows_1256</literal></entry>
2685        <entry><literal>UTF8</literal></entry>
2686        <entry><literal>WIN1256</literal></entry>
2687       </row>
2688
2689       <row>
2690        <entry><literal>utf8_to_windows_1257</literal></entry>
2691        <entry><literal>UTF8</literal></entry>
2692        <entry><literal>WIN1257</literal></entry>
2693       </row>
2694
2695       <row>
2696        <entry><literal>utf8_to_windows_866</literal></entry>
2697        <entry><literal>UTF8</literal></entry>
2698        <entry><literal>WIN866</literal></entry>
2699       </row>
2700
2701       <row>
2702        <entry><literal>utf8_to_windows_874</literal></entry>
2703        <entry><literal>UTF8</literal></entry>
2704        <entry><literal>WIN874</literal></entry>
2705       </row>
2706
2707       <row>
2708        <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
2709        <entry><literal>WIN1250</literal></entry>
2710        <entry><literal>LATIN2</literal></entry>
2711       </row>
2712
2713       <row>
2714        <entry><literal>windows_1250_to_mic</literal></entry>
2715        <entry><literal>WIN1250</literal></entry>
2716        <entry><literal>MULE_INTERNAL</literal></entry>
2717       </row>
2718
2719       <row>
2720        <entry><literal>windows_1250_to_utf8</literal></entry>
2721        <entry><literal>WIN1250</literal></entry>
2722        <entry><literal>UTF8</literal></entry>
2723       </row>
2724
2725       <row>
2726        <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
2727        <entry><literal>WIN1251</literal></entry>
2728        <entry><literal>ISO_8859_5</literal></entry>
2729       </row>
2730
2731       <row>
2732        <entry><literal>windows_1251_to_koi8_r</literal></entry>
2733        <entry><literal>WIN1251</literal></entry>
2734        <entry><literal>KOI8R</literal></entry>
2735       </row>
2736
2737       <row>
2738        <entry><literal>windows_1251_to_mic</literal></entry>
2739        <entry><literal>WIN1251</literal></entry>
2740        <entry><literal>MULE_INTERNAL</literal></entry>
2741       </row>
2742
2743       <row>
2744        <entry><literal>windows_1251_to_utf8</literal></entry>
2745        <entry><literal>WIN1251</literal></entry>
2746        <entry><literal>UTF8</literal></entry>
2747       </row>
2748
2749       <row>
2750        <entry><literal>windows_1251_to_windows_866</literal></entry>
2751        <entry><literal>WIN1251</literal></entry>
2752        <entry><literal>WIN866</literal></entry>
2753       </row>
2754
2755       <row>
2756        <entry><literal>windows_1252_to_utf8</literal></entry>
2757        <entry><literal>WIN1252</literal></entry>
2758        <entry><literal>UTF8</literal></entry>
2759       </row>
2760
2761       <row>
2762        <entry><literal>windows_1256_to_utf8</literal></entry>
2763        <entry><literal>WIN1256</literal></entry>
2764        <entry><literal>UTF8</literal></entry>
2765       </row>
2766
2767       <row>
2768        <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2769        <entry><literal>WIN866</literal></entry>
2770        <entry><literal>ISO_8859_5</literal></entry>
2771       </row>
2772
2773       <row>
2774        <entry><literal>windows_866_to_koi8_r</literal></entry>
2775        <entry><literal>WIN866</literal></entry>
2776        <entry><literal>KOI8R</literal></entry>
2777       </row>
2778
2779       <row>
2780        <entry><literal>windows_866_to_mic</literal></entry>
2781        <entry><literal>WIN866</literal></entry>
2782        <entry><literal>MULE_INTERNAL</literal></entry>
2783       </row>
2784
2785       <row>
2786        <entry><literal>windows_866_to_utf8</literal></entry>
2787        <entry><literal>WIN866</literal></entry>
2788        <entry><literal>UTF8</literal></entry>
2789       </row>
2790
2791       <row>
2792        <entry><literal>windows_866_to_windows_1251</literal></entry>
2793        <entry><literal>WIN866</literal></entry>
2794        <entry><literal>WIN</literal></entry>
2795       </row>
2796
2797       <row>
2798        <entry><literal>windows_874_to_utf8</literal></entry>
2799        <entry><literal>WIN874</literal></entry>
2800        <entry><literal>UTF8</literal></entry>
2801       </row>
2802
2803       <row>
2804        <entry><literal>euc_jis_2004_to_utf8</literal></entry>
2805        <entry><literal>EUC_JIS_2004</literal></entry>
2806        <entry><literal>UTF8</literal></entry>
2807       </row>
2808
2809       <row>
2810        <entry><literal>ut8_to_euc_jis_2004</literal></entry>
2811        <entry><literal>UTF8</literal></entry>
2812        <entry><literal>EUC_JIS_2004</literal></entry>
2813       </row>
2814
2815       <row>
2816        <entry><literal>shift_jis_2004_to_utf8</literal></entry>
2817        <entry><literal>SHIFT_JIS_2004</literal></entry>
2818        <entry><literal>UTF8</literal></entry>
2819       </row>
2820
2821       <row>
2822        <entry><literal>ut8_to_shift_jis_2004</literal></entry>
2823        <entry><literal>UTF8</literal></entry>
2824        <entry><literal>SHIFT_JIS_2004</literal></entry>
2825       </row>
2826
2827       <row>
2828        <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
2829        <entry><literal>EUC_JIS_2004</literal></entry>
2830        <entry><literal>SHIFT_JIS_2004</literal></entry>
2831       </row>
2832
2833       <row>
2834        <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
2835        <entry><literal>SHIFT_JIS_2004</literal></entry>
2836        <entry><literal>EUC_JIS_2004</literal></entry>
2837       </row>
2838
2839      </tbody>
2840     </tgroup>
2841    </table>
2842
2843    <sect2 id="functions-string-format">
2844     <title><function>format</function></title>
2845
2846     <indexterm>
2847      <primary>format</primary>
2848     </indexterm>
2849
2850     <para>
2851      The function <function>format</> produces output formatted according to
2852      a format string, in a style similar to the C function
2853      <function>sprintf</>.
2854     </para>
2855
2856     <para>
2857 <synopsis>
2858 <function>format</>(<parameter>formatstr</> <type>text</> [, <parameter>formatarg</> <type>"any"</> [, ...] ])
2859 </synopsis>
2860      <replaceable>formatstr</> is a format string that specifies how the
2861      result should be formatted.  Text in the format string is copied
2862      directly to the result, except where <firstterm>format specifiers</> are
2863      used.  Format specifiers act as placeholders in the string, defining how
2864      subsequent function arguments should be formatted and inserted into the
2865      result.  Each <replaceable>formatarg</> argument is converted to text
2866      according to the usual output rules for its data type, and then formatted
2867      and inserted into the result string according to the format specifier(s).
2868     </para>
2869
2870     <para>
2871      Format specifiers are introduced by a <literal>%</> character and have
2872      the form
2873 <synopsis>
2874 %[<replaceable>position</>][<replaceable>flags</>][<replaceable>width</>]<replaceable>type</>
2875 </synopsis>
2876      where the component fields are:
2877
2878      <variablelist>
2879       <varlistentry>
2880        <term><replaceable>position</replaceable> (optional)</term>
2881        <listitem>
2882         <para>
2883          A string of the form <literal><replaceable>n</>$</> where
2884          <replaceable>n</> is the index of the argument to print.
2885          Index 1 means the first argument after
2886          <replaceable>formatstr</>.  If the <replaceable>position</> is
2887          omitted, the default is to use the next argument in sequence.
2888         </para>
2889        </listitem>
2890       </varlistentry>
2891
2892       <varlistentry>
2893        <term><replaceable>flags</replaceable> (optional)</term>
2894        <listitem>
2895         <para>
2896          Additional options controlling how the format specifier's output is
2897          formatted.  Currently the only supported flag is a minus sign
2898          (<literal>-</>) which will cause the format specifier's output to be
2899          left-justified.  This has no effect unless the <replaceable>width</>
2900          field is also specified.
2901         </para>
2902        </listitem>
2903       </varlistentry>
2904
2905       <varlistentry>
2906        <term><replaceable>width</replaceable> (optional)</term>
2907        <listitem>
2908         <para>
2909          Specifies the <emphasis>minimum</> number of characters to use to
2910          display the format specifier's output.  The output is padded on the
2911          left or right (depending on the <literal>-</> flag) with spaces as
2912          needed to fill the width.  A too-small width does not cause
2913          truncation of the output, but is simply ignored.  The width may be
2914          specified using any of the following: a positive integer; an
2915          asterisk (<literal>*</>) to use the next function argument as the
2916          width; or a string of the form <literal>*<replaceable>n</>$</> to
2917          use the <replaceable>n</>th function argument as the width.
2918         </para>
2919
2920         <para>
2921          If the width comes from a function argument, that argument is
2922          consumed before the argument that is used for the format specifier's
2923          value.  If the width argument is negative, the result is left
2924          aligned (as if the <literal>-</> flag had been specified) within a
2925          field of length <function>abs</>(<replaceable>width</replaceable>).
2926         </para>
2927        </listitem>
2928       </varlistentry>
2929
2930       <varlistentry>
2931        <term><replaceable>type</replaceable> (required)</term>
2932        <listitem>
2933         <para>
2934          The type of format conversion to use to produce the format
2935          specifier's output.  The following types are supported:
2936          <itemizedlist>
2937           <listitem>
2938            <para>
2939             <literal>s</literal> formats the argument value as a simple
2940             string.  A null value is treated as an empty string.
2941            </para>
2942           </listitem>
2943           <listitem>
2944            <para>
2945             <literal>I</literal> treats the argument value as an SQL
2946             identifier, double-quoting it if necessary.
2947             It is an error for the value to be null.
2948            </para>
2949           </listitem>
2950           <listitem>
2951            <para>
2952             <literal>L</literal> quotes the argument value as an SQL literal.
2953             A null value is displayed as the string <literal>NULL</>, without
2954             quotes.
2955            </para>
2956           </listitem>
2957          </itemizedlist>
2958         </para>
2959        </listitem>
2960       </varlistentry>
2961      </variablelist>
2962     </para>
2963
2964     <para>
2965      In addition to the format specifiers described above, the special sequence
2966      <literal>%%</> may be used to output a literal <literal>%</> character.
2967     </para>
2968
2969     <para>
2970      Here are some examples of the basic format conversions:
2971
2972 <screen>
2973 SELECT format('Hello %s', 'World');
2974 <lineannotation>Result: </lineannotation><computeroutput>Hello World</computeroutput>
2975
2976 SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
2977 <lineannotation>Result: </><computeroutput>Testing one, two, three, %</>
2978
2979 SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
2980 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO "Foo bar" VALUES('O''Reilly')</computeroutput>
2981
2982 SELECT format('INSERT INTO %I VALUES(%L)', 'locations', E'C:\\Program Files');
2983 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO locations VALUES(E'C:\\Program Files')</computeroutput>
2984 </screen>
2985     </para>
2986
2987     <para>
2988      Here are examples using <replaceable>width</replaceable> fields
2989      and the <literal>-</> flag:
2990
2991 <screen>
2992 SELECT format('|%10s|', 'foo');
2993 <lineannotation>Result: </><computeroutput>|       foo|</>
2994
2995 SELECT format('|%-10s|', 'foo');
2996 <lineannotation>Result: </><computeroutput>|foo       |</>
2997
2998 SELECT format('|%*s|', 10, 'foo');
2999 <lineannotation>Result: </><computeroutput>|       foo|</>
3000
3001 SELECT format('|%*s|', -10, 'foo');
3002 <lineannotation>Result: </><computeroutput>|foo       |</>
3003
3004 SELECT format('|%-*s|', 10, 'foo');
3005 <lineannotation>Result: </><computeroutput>|foo       |</>
3006
3007 SELECT format('|%-*s|', -10, 'foo');
3008 <lineannotation>Result: </><computeroutput>|foo       |</>
3009 </screen>
3010     </para>
3011
3012     <para>
3013      These examples show use of <replaceable>position</> fields:
3014
3015 <screen>
3016 SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three');
3017 <lineannotation>Result: </><computeroutput>Testing three, two, one</>
3018
3019 SELECT format('|%*2$s|', 'foo', 10, 'bar');
3020 <lineannotation>Result: </><computeroutput>|       bar|</>
3021
3022 SELECT format('|%1$*2$s|', 'foo', 10, 'bar');
3023 <lineannotation>Result: </><computeroutput>|       foo|</>
3024 </screen>
3025     </para>
3026
3027     <para>
3028      Unlike the standard C function <function>sprintf</>,
3029      <productname>PostgreSQL</>'s <function>format</> function allows format
3030      specifiers with and without <replaceable>position</> fields to be mixed
3031      in the same format string.  A format specifier without a
3032      <replaceable>position</> field always uses the next argument after the
3033      last argument consumed.
3034      In addition, the <function>format</> function does not require all
3035      function arguments to be used in the format string.
3036      For example:
3037
3038 <screen>
3039 SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three');
3040 <lineannotation>Result: </><computeroutput>Testing three, two, three</>
3041 </screen>
3042     </para>
3043
3044     <para>
3045      The <literal>%I</> and <literal>%L</> format specifiers are particularly
3046      useful for safely constructing dynamic SQL statements.  See
3047      <xref linkend="plpgsql-quote-literal-example">.
3048     </para>
3049    </sect2>
3050
3051   </sect1>
3052
3053
3054   <sect1 id="functions-binarystring">
3055    <title>Binary String Functions and Operators</title>
3056
3057    <indexterm zone="functions-binarystring">
3058     <primary>binary data</primary>
3059     <secondary>functions</secondary>
3060    </indexterm>
3061
3062    <para>
3063     This section describes functions and operators for examining and
3064     manipulating values of type <type>bytea</type>.
3065    </para>
3066
3067    <para>
3068     <acronym>SQL</acronym> defines some string functions that use
3069     key words, rather than commas, to separate
3070     arguments.  Details are in
3071     <xref linkend="functions-binarystring-sql">.
3072     <productname>PostgreSQL</> also provides versions of these functions
3073     that use the regular function invocation syntax
3074     (see <xref linkend="functions-binarystring-other">).
3075    </para>
3076
3077    <note>
3078     <para>
3079      The sample results shown on this page assume that the server parameter
3080      <link linkend="guc-bytea-output"><varname>bytea_output</></link> is set
3081      to <literal>escape</literal> (the traditional PostgreSQL format).
3082     </para>
3083    </note>
3084
3085    <table id="functions-binarystring-sql">
3086     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
3087     <tgroup cols="5">
3088      <thead>
3089       <row>
3090        <entry>Function</entry>
3091        <entry>Return Type</entry>
3092        <entry>Description</entry>
3093        <entry>Example</entry>
3094        <entry>Result</entry>
3095       </row>
3096      </thead>
3097
3098      <tbody>
3099       <row>
3100        <entry><literal><parameter>string</parameter> <literal>||</literal>
3101         <parameter>string</parameter></literal></entry>
3102        <entry> <type>bytea</type> </entry>
3103        <entry>
3104         String concatenation
3105         <indexterm>
3106          <primary>binary string</primary>
3107          <secondary>concatenation</secondary>
3108         </indexterm>
3109        </entry>
3110        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
3111        <entry><literal>\\Post'gres\000</literal></entry>
3112       </row>
3113
3114       <row>
3115        <entry>
3116         <indexterm>
3117          <primary>octet_length</primary>
3118         </indexterm>
3119         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
3120        </entry>
3121        <entry><type>int</type></entry>
3122        <entry>Number of bytes in binary string</entry>
3123        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
3124        <entry><literal>5</literal></entry>
3125       </row>
3126
3127       <row>
3128        <entry>
3129         <indexterm>
3130          <primary>overlay</primary>
3131         </indexterm>
3132         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
3133        </entry>
3134        <entry><type>bytea</type></entry>
3135        <entry>
3136         Replace substring
3137        </entry>
3138        <entry><literal>overlay(E'Th\\000omas'::bytea placing E'\\002\\003'::bytea from 2 for 3)</literal></entry>
3139        <entry><literal>T\\002\\003mas</literal></entry>
3140       </row>
3141
3142       <row>
3143        <entry>
3144         <indexterm>
3145          <primary>position</primary>
3146         </indexterm>
3147         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
3148        </entry>
3149        <entry><type>int</type></entry>
3150        <entry>Location of specified substring</entry>
3151       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
3152        <entry><literal>3</literal></entry>
3153       </row>
3154
3155       <row>
3156        <entry>
3157         <indexterm>
3158          <primary>substring</primary>
3159         </indexterm>
3160         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
3161        </entry>
3162        <entry><type>bytea</type></entry>
3163        <entry>
3164         Extract substring
3165        </entry>
3166        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
3167        <entry><literal>h\000o</literal></entry>
3168       </row>
3169
3170       <row>
3171        <entry>
3172         <indexterm>
3173          <primary>trim</primary>
3174         </indexterm>
3175         <literal><function>trim(<optional>both</optional>
3176         <parameter>bytes</parameter> from
3177         <parameter>string</parameter>)</function></literal>
3178        </entry>
3179        <entry><type>bytea</type></entry>
3180        <entry>
3181         Remove the longest string containing only the bytes in
3182         <parameter>bytes</parameter> from the start
3183         and end of <parameter>string</parameter>
3184        </entry>
3185        <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
3186        <entry><literal>Tom</literal></entry>
3187       </row>
3188      </tbody>
3189     </tgroup>
3190    </table>
3191
3192    <para>
3193     Additional binary string manipulation functions are available and
3194     are listed in <xref linkend="functions-binarystring-other">.  Some
3195     of them are used internally to implement the
3196     <acronym>SQL</acronym>-standard string functions listed in <xref
3197     linkend="functions-binarystring-sql">.
3198    </para>
3199
3200    <table id="functions-binarystring-other">
3201     <title>Other Binary String Functions</title>
3202     <tgroup cols="5">
3203      <thead>
3204       <row>
3205        <entry>Function</entry>
3206        <entry>Return Type</entry>
3207        <entry>Description</entry>
3208        <entry>Example</entry>
3209        <entry>Result</entry>
3210       </row>
3211      </thead>
3212
3213      <tbody>
3214       <row>
3215        <entry>
3216         <indexterm>
3217          <primary>btrim</primary>
3218         </indexterm>
3219         <literal><function>btrim(<parameter>string</parameter>
3220         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</function></literal>
3221        </entry>
3222        <entry><type>bytea</type></entry>
3223        <entry>
3224         Remove the longest string consisting only of bytes
3225         in <parameter>bytes</parameter> from the start and end of
3226         <parameter>string</parameter>
3227       </entry>
3228       <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
3229       <entry><literal>trim</literal></entry>
3230      </row>
3231
3232      <row>
3233       <entry>
3234         <indexterm>
3235          <primary>decode</primary>
3236         </indexterm>
3237        <literal><function>decode(<parameter>string</parameter> <type>text</type>,
3238        <parameter>format</parameter> <type>text</type>)</function></literal>
3239       </entry>
3240       <entry><type>bytea</type></entry>
3241       <entry>
3242        Decode binary data from textual representation in <parameter>string</>.
3243        Options for <parameter>format</> are same as in <function>encode</>.
3244       </entry>
3245       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
3246       <entry><literal>123\000456</literal></entry>
3247      </row>
3248
3249      <row>
3250       <entry>
3251         <indexterm>
3252          <primary>encode</primary>
3253         </indexterm>
3254        <literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
3255        <parameter>format</parameter> <type>text</type>)</function></literal>
3256       </entry>
3257       <entry><type>text</type></entry>
3258       <entry>
3259        Encode binary data into a textual representation.  Supported
3260        formats are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
3261        <literal>escape</> converts zero bytes and high-bit-set bytes to
3262        octal sequences (<literal>\</><replaceable>nnn</>) and
3263        doubles backslashes.
3264       </entry>
3265       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
3266       <entry><literal>123\000456</literal></entry>
3267      </row>
3268
3269       <row>
3270        <entry>
3271         <indexterm>
3272          <primary>get_bit</primary>
3273         </indexterm>
3274         <literal><function>get_bit(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3275        </entry>
3276        <entry><type>int</type></entry>
3277        <entry>
3278         Extract bit from string
3279        </entry>
3280        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
3281        <entry><literal>1</literal></entry>
3282       </row>
3283
3284       <row>
3285        <entry>
3286         <indexterm>
3287          <primary>get_byte</primary>
3288         </indexterm>
3289         <literal><function>get_byte(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3290        </entry>
3291        <entry><type>int</type></entry>
3292        <entry>
3293         Extract byte from string
3294        </entry>
3295        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
3296        <entry><literal>109</literal></entry>
3297       </row>
3298
3299      <row>
3300       <entry>
3301        <indexterm>
3302         <primary>length</primary>
3303        </indexterm>
3304        <literal><function>length(<parameter>string</parameter>)</function></literal>
3305       </entry>
3306       <entry><type>int</type></entry>
3307       <entry>
3308        Length of binary string
3309        <indexterm>
3310         <primary>binary string</primary>
3311         <secondary>length</secondary>
3312        </indexterm>
3313        <indexterm>
3314         <primary>length</primary>
3315         <secondary sortas="binary string">of a binary string</secondary>
3316         <see>binary strings, length</see>
3317        </indexterm>
3318       </entry>
3319       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
3320       <entry><literal>5</literal></entry>
3321      </row>
3322
3323      <row>
3324       <entry>
3325        <indexterm>
3326         <primary>md5</primary>
3327        </indexterm>
3328        <literal><function>md5(<parameter>string</parameter>)</function></literal>
3329       </entry>
3330       <entry><type>text</type></entry>
3331       <entry>
3332        Calculates the MD5 hash of <parameter>string</parameter>,
3333        returning the result in hexadecimal
3334       </entry>
3335       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
3336       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
3337      </row>
3338
3339       <row>
3340        <entry>
3341         <indexterm>
3342          <primary>set_bit</primary>
3343         </indexterm>
3344         <literal><function>set_bit(<parameter>string</parameter>,
3345         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3346        </entry>
3347        <entry><type>bytea</type></entry>
3348        <entry>
3349         Set bit in string
3350        </entry>
3351        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
3352        <entry><literal>Th\000omAs</literal></entry>
3353       </row>
3354
3355       <row>
3356        <entry>
3357         <indexterm>
3358          <primary>set_byte</primary>
3359         </indexterm>
3360         <literal><function>set_byte(<parameter>string</parameter>,
3361         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3362        </entry>
3363        <entry><type>bytea</type></entry>
3364        <entry>
3365         Set byte in string
3366        </entry>
3367        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
3368        <entry><literal>Th\000o@as</literal></entry>
3369       </row>
3370     </tbody>
3371    </tgroup>
3372   </table>
3373
3374   <para>
3375    <function>get_byte</> and <function>set_byte</> number the first byte
3376    of a binary string as byte 0.
3377    <function>get_bit</> and <function>set_bit</> number bits from the
3378    right within each byte; for example bit 0 is the least significant bit of
3379    the first byte, and bit 15 is the most significant bit of the second byte.
3380   </para>
3381
3382   <para>
3383    See also the aggregate function <function>string_agg</function> in
3384    <xref linkend="functions-aggregate">.
3385   </para>
3386  </sect1>
3387
3388
3389   <sect1 id="functions-bitstring">
3390    <title>Bit String Functions and Operators</title>
3391
3392    <indexterm zone="functions-bitstring">
3393     <primary>bit strings</primary>
3394     <secondary>functions</secondary>
3395    </indexterm>
3396
3397    <para>
3398     This section describes functions and operators for examining and
3399     manipulating bit strings, that is values of the types
3400     <type>bit</type> and <type>bit varying</type>.  Aside from the
3401     usual comparison operators, the operators
3402     shown in <xref linkend="functions-bit-string-op-table"> can be used.
3403     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
3404     and <literal>#</literal> must be of equal length.  When bit
3405     shifting, the original length of the string is preserved, as shown
3406     in the examples.
3407    </para>
3408
3409    <table id="functions-bit-string-op-table">
3410     <title>Bit String Operators</title>
3411
3412     <tgroup cols="4">
3413      <thead>
3414       <row>
3415        <entry>Operator</entry>
3416        <entry>Description</entry>
3417        <entry>Example</entry>
3418        <entry>Result</entry>
3419       </row>
3420      </thead>
3421
3422      <tbody>
3423       <row>
3424        <entry> <literal>||</literal> </entry>
3425        <entry>concatenation</entry>
3426        <entry><literal>B'10001' || B'011'</literal></entry>
3427        <entry><literal>10001011</literal></entry>
3428       </row>
3429
3430       <row>
3431        <entry> <literal>&amp;</literal> </entry>
3432        <entry>bitwise AND</entry>
3433        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
3434        <entry><literal>00001</literal></entry>
3435       </row>
3436
3437       <row>
3438        <entry> <literal>|</literal> </entry>
3439        <entry>bitwise OR</entry>
3440        <entry><literal>B'10001' | B'01101'</literal></entry>
3441        <entry><literal>11101</literal></entry>
3442       </row>
3443
3444       <row>
3445        <entry> <literal>#</literal> </entry>
3446        <entry>bitwise XOR</entry>
3447        <entry><literal>B'10001' # B'01101'</literal></entry>
3448        <entry><literal>11100</literal></entry>
3449       </row>
3450
3451       <row>
3452        <entry> <literal>~</literal> </entry>
3453        <entry>bitwise NOT</entry>
3454        <entry><literal>~ B'10001'</literal></entry>
3455        <entry><literal>01110</literal></entry>
3456       </row>
3457
3458       <row>
3459        <entry> <literal>&lt;&lt;</literal> </entry>
3460        <entry>bitwise shift left</entry>
3461        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
3462        <entry><literal>01000</literal></entry>
3463       </row>
3464
3465       <row>
3466        <entry> <literal>&gt;&gt;</literal> </entry>
3467        <entry>bitwise shift right</entry>
3468        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
3469        <entry><literal>00100</literal></entry>
3470       </row>
3471      </tbody>
3472     </tgroup>
3473    </table>
3474
3475    <para>
3476     The following <acronym>SQL</acronym>-standard functions work on bit
3477     strings as well as character strings:
3478     <literal><function>length</function></literal>,
3479     <literal><function>bit_length</function></literal>,
3480     <literal><function>octet_length</function></literal>,
3481     <literal><function>position</function></literal>,
3482     <literal><function>substring</function></literal>,
3483     <literal><function>overlay</function></literal>.
3484    </para>
3485
3486    <para>
3487     The following functions work on bit strings as well as binary
3488     strings:
3489     <literal><function>get_bit</function></literal>,
3490     <literal><function>set_bit</function></literal>.
3491     When working with a bit string, these functions number the first
3492     (leftmost) bit of the string as bit 0.
3493    </para>
3494
3495    <para>
3496     In addition, it is possible to cast integral values to and from type
3497     <type>bit</>.
3498     Some examples:
3499 <programlisting>
3500 44::bit(10)                    <lineannotation>0000101100</lineannotation>
3501 44::bit(3)                     <lineannotation>100</lineannotation>
3502 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
3503 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
3504 </programlisting>
3505     Note that casting to just <quote>bit</> means casting to
3506     <literal>bit(1)</>, and so will deliver only the least significant
3507     bit of the integer.
3508    </para>
3509
3510     <note>
3511      <para>
3512       Prior to <productname>PostgreSQL</productname> 8.0, casting an
3513       integer to <type>bit(n)</> would copy the leftmost <literal>n</>
3514       bits of the integer, whereas now it copies the rightmost <literal>n</>
3515       bits.  Also, casting an integer to a bit string width wider than
3516       the integer itself will sign-extend on the left.
3517      </para>
3518     </note>
3519
3520   </sect1>
3521
3522
3523  <sect1 id="functions-matching">
3524   <title>Pattern Matching</title>
3525
3526   <indexterm zone="functions-matching">
3527    <primary>pattern matching</primary>
3528   </indexterm>
3529
3530    <para>
3531     There are three separate approaches to pattern matching provided
3532     by <productname>PostgreSQL</productname>: the traditional
3533     <acronym>SQL</acronym> <function>LIKE</function> operator, the
3534     more recent <function>SIMILAR TO</function> operator (added in
3535     SQL:1999), and <acronym>POSIX</acronym>-style regular
3536     expressions.  Aside from the basic <quote>does this string match
3537     this pattern?</> operators, functions are available to extract
3538     or replace matching substrings and to split a string at matching
3539     locations.
3540    </para>
3541
3542    <tip>
3543     <para>
3544      If you have pattern matching needs that go beyond this,
3545      consider writing a user-defined function in Perl or Tcl.
3546     </para>
3547    </tip>
3548
3549   <sect2 id="functions-like">
3550    <title><function>LIKE</function></title>
3551
3552    <indexterm>
3553     <primary>LIKE</primary>
3554    </indexterm>
3555
3556 <synopsis>
3557 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3558 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3559 </synopsis>
3560
3561     <para>
3562      The <function>LIKE</function> expression returns true if the
3563      <replaceable>string</replaceable> matches the supplied
3564      <replaceable>pattern</replaceable>.  (As
3565      expected, the <function>NOT LIKE</function> expression returns
3566      false if <function>LIKE</function> returns true, and vice versa.
3567      An equivalent expression is
3568      <literal>NOT (<replaceable>string</replaceable> LIKE
3569       <replaceable>pattern</replaceable>)</literal>.)
3570     </para>
3571
3572     <para>
3573      If <replaceable>pattern</replaceable> does not contain percent
3574      signs or underscores, then the pattern only represents the string
3575      itself; in that case <function>LIKE</function> acts like the
3576      equals operator.  An underscore (<literal>_</literal>) in
3577      <replaceable>pattern</replaceable> stands for (matches) any single
3578      character; a percent sign (<literal>%</literal>) matches any sequence
3579      of zero or more characters.
3580     </para>
3581
3582    <para>
3583     Some examples:
3584 <programlisting>
3585 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
3586 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
3587 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
3588 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
3589 </programlisting>
3590    </para>
3591
3592    <para>
3593     <function>LIKE</function> pattern matching always covers the entire
3594     string.  Therefore, if it's desired to match a sequence anywhere within
3595     a string, the pattern must start and end with a percent sign.
3596    </para>
3597
3598    <para>
3599     To match a literal underscore or percent sign without matching
3600     other characters, the respective character in
3601     <replaceable>pattern</replaceable> must be
3602     preceded by the escape character.  The default escape
3603     character is the backslash but a different one can be selected by
3604     using the <literal>ESCAPE</literal> clause.  To match the escape
3605     character itself, write two escape characters.
3606    </para>
3607
3608    <note>
3609     <para>
3610      If you have <xref linkend="guc-standard-conforming-strings"> turned off,
3611      any backslashes you write in literal string constants will need to be
3612      doubled.  See <xref linkend="sql-syntax-strings"> for more information.
3613     </para>
3614    </note>
3615
3616    <para>
3617     It's also possible to select no escape character by writing
3618     <literal>ESCAPE ''</literal>.  This effectively disables the
3619     escape mechanism, which makes it impossible to turn off the
3620     special meaning of underscore and percent signs in the pattern.
3621    </para>
3622
3623    <para>
3624     The key word <token>ILIKE</token> can be used instead of
3625     <token>LIKE</token> to make the match case-insensitive according
3626     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3627     <productname>PostgreSQL</productname> extension.
3628    </para>
3629
3630    <para>
3631     The operator <literal>~~</literal> is equivalent to
3632     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3633     <function>ILIKE</function>.  There are also
3634     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3635     represent <function>NOT LIKE</function> and <function>NOT
3636     ILIKE</function>, respectively.  All of these operators are
3637     <productname>PostgreSQL</productname>-specific.
3638    </para>
3639   </sect2>
3640
3641
3642   <sect2 id="functions-similarto-regexp">
3643    <title><function>SIMILAR TO</function> Regular Expressions</title>
3644
3645    <indexterm>
3646     <primary>regular expression</primary>
3647     <!-- <seealso>pattern matching</seealso> breaks index build -->
3648    </indexterm>
3649
3650    <indexterm>
3651     <primary>SIMILAR TO</primary>
3652    </indexterm>
3653    <indexterm>
3654     <primary>substring</primary>
3655    </indexterm>
3656
3657 <synopsis>
3658 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3659 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3660 </synopsis>
3661
3662    <para>
3663     The <function>SIMILAR TO</function> operator returns true or
3664     false depending on whether its pattern matches the given string.
3665     It is similar to <function>LIKE</function>, except that it
3666     interprets the pattern using the SQL standard's definition of a
3667     regular expression.  SQL regular expressions are a curious cross
3668     between <function>LIKE</function> notation and common regular
3669     expression notation.
3670    </para>
3671
3672    <para>
3673     Like <function>LIKE</function>, the <function>SIMILAR TO</function>
3674     operator succeeds only if its pattern matches the entire string;
3675     this is unlike common regular expression behavior where the pattern
3676     can match any part of the string.
3677     Also like
3678     <function>LIKE</function>, <function>SIMILAR TO</function> uses
3679     <literal>_</> and <literal>%</> as wildcard characters denoting
3680     any single character and any string, respectively (these are
3681     comparable to <literal>.</> and <literal>.*</> in POSIX regular
3682     expressions).
3683    </para>
3684
3685    <para>
3686     In addition to these facilities borrowed from <function>LIKE</function>,
3687     <function>SIMILAR TO</function> supports these pattern-matching
3688     metacharacters borrowed from POSIX regular expressions:
3689
3690    <itemizedlist>
3691     <listitem>
3692      <para>
3693       <literal>|</literal> denotes alternation (either of two alternatives).
3694      </para>
3695     </listitem>
3696     <listitem>
3697      <para>
3698       <literal>*</literal> denotes repetition of the previous item zero
3699       or more times.
3700      </para>
3701     </listitem>
3702     <listitem>
3703      <para>
3704       <literal>+</literal> denotes repetition of the previous item one
3705       or more times.
3706      </para>
3707     </listitem>
3708     <listitem>
3709      <para>
3710       <literal>?</literal> denotes repetition of the previous item zero
3711       or one time.
3712      </para>
3713     </listitem>
3714     <listitem>
3715      <para>
3716       <literal>{</><replaceable>m</><literal>}</literal> denotes repetition
3717       of the previous item exactly <replaceable>m</> times.
3718      </para>
3719     </listitem>
3720     <listitem>
3721      <para>
3722       <literal>{</><replaceable>m</><literal>,}</literal> denotes repetition
3723       of the previous item <replaceable>m</> or more times.
3724      </para>
3725     </listitem>
3726     <listitem>
3727      <para>
3728       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
3729       denotes repetition of the previous item at least <replaceable>m</> and
3730       not more than <replaceable>n</> times.
3731      </para>
3732     </listitem>
3733     <listitem>
3734      <para>
3735       Parentheses <literal>()</literal> can be used to group items into
3736       a single logical item.
3737      </para>
3738     </listitem>
3739     <listitem>
3740      <para>
3741       A bracket expression <literal>[...]</literal> specifies a character
3742       class, just as in POSIX regular expressions.
3743      </para>
3744     </listitem>
3745    </itemizedlist>
3746
3747     Notice that the period (<literal>.</>) is not a metacharacter
3748     for <function>SIMILAR TO</>.
3749    </para>
3750
3751    <para>
3752     As with <function>LIKE</>, a backslash disables the special meaning
3753     of any of these metacharacters; or a different escape character can
3754     be specified with <literal>ESCAPE</>.
3755    </para>
3756
3757    <para>
3758     Some examples:
3759 <programlisting>
3760 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
3761 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
3762 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
3763 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
3764 </programlisting>
3765    </para>
3766
3767    <para>
3768     The <function>substring</> function with three parameters,
3769     <function>substring(<replaceable>string</replaceable> from
3770     <replaceable>pattern</replaceable> for
3771     <replaceable>escape-character</replaceable>)</function>, provides
3772     extraction of a substring that matches an SQL
3773     regular expression pattern.  As with <literal>SIMILAR TO</>, the
3774     specified pattern must match the entire data string, or else the
3775     function fails and returns null.  To indicate the part of the
3776     pattern that should be returned on success, the pattern must contain
3777     two occurrences of the escape character followed by a double quote
3778     (<literal>"</>). <!-- " font-lock sanity -->
3779     The text matching the portion of the pattern
3780     between these markers is returned.
3781    </para>
3782
3783    <para>
3784     Some examples, with <literal>#&quot;</> delimiting the return string:
3785 <programlisting>
3786 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
3787 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
3788 </programlisting>
3789    </para>
3790   </sect2>
3791
3792   <sect2 id="functions-posix-regexp">
3793    <title><acronym>POSIX</acronym> Regular Expressions</title>
3794
3795    <indexterm zone="functions-posix-regexp">
3796     <primary>regular expression</primary>
3797     <seealso>pattern matching</seealso>
3798    </indexterm>
3799    <indexterm>
3800     <primary>substring</primary>
3801    </indexterm>
3802    <indexterm>
3803     <primary>regexp_replace</primary>
3804    </indexterm>
3805    <indexterm>
3806     <primary>regexp_matches</primary>
3807    </indexterm>
3808    <indexterm>
3809     <primary>regexp_split_to_table</primary>
3810    </indexterm>
3811    <indexterm>
3812     <primary>regexp_split_to_array</primary>
3813    </indexterm>
3814
3815    <para>
3816     <xref linkend="functions-posix-table"> lists the available
3817     operators for pattern matching using POSIX regular expressions.
3818    </para>
3819
3820    <table id="functions-posix-table">
3821     <title>Regular Expression Match Operators</title>
3822
3823     <tgroup cols="3">
3824      <thead>
3825       <row>
3826        <entry>Operator</entry>
3827        <entry>Description</entry>
3828        <entry>Example</entry>
3829       </row>
3830      </thead>
3831
3832       <tbody>
3833        <row>
3834         <entry> <literal>~</literal> </entry>
3835         <entry>Matches regular expression, case sensitive</entry>
3836         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3837        </row>
3838
3839        <row>
3840         <entry> <literal>~*</literal> </entry>
3841         <entry>Matches regular expression, case insensitive</entry>
3842         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3843        </row>
3844
3845        <row>
3846         <entry> <literal>!~</literal> </entry>
3847         <entry>Does not match regular expression, case sensitive</entry>
3848         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3849        </row>
3850
3851        <row>
3852         <entry> <literal>!~*</literal> </entry>
3853         <entry>Does not match regular expression, case insensitive</entry>
3854         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3855        </row>
3856       </tbody>
3857      </tgroup>
3858     </table>
3859
3860     <para>
3861      <acronym>POSIX</acronym> regular expressions provide a more
3862      powerful means for pattern matching than the <function>LIKE</function> and
3863      <function>SIMILAR TO</> operators.
3864      Many Unix tools such as <command>egrep</command>,
3865      <command>sed</command>, or <command>awk</command> use a pattern
3866      matching language that is similar to the one described here.
3867     </para>
3868
3869     <para>
3870      A regular expression is a character sequence that is an
3871      abbreviated definition of a set of strings (a <firstterm>regular
3872      set</firstterm>).  A string is said to match a regular expression
3873      if it is a member of the regular set described by the regular
3874      expression.  As with <function>LIKE</function>, pattern characters
3875      match string characters exactly unless they are special characters
3876      in the regular expression language &mdash; but regular expressions use
3877      different special characters than <function>LIKE</function> does.
3878      Unlike <function>LIKE</function> patterns, a
3879      regular expression is allowed to match anywhere within a string, unless
3880      the regular expression is explicitly anchored to the beginning or
3881      end of the string.
3882     </para>
3883
3884     <para>
3885      Some examples:
3886 <programlisting>
3887 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
3888 'abc' ~ '^a'     <lineannotation>true</lineannotation>
3889 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
3890 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3891 </programlisting>
3892     </para>
3893
3894     <para>
3895      The <acronym>POSIX</acronym> pattern language is described in much
3896      greater detail below.
3897     </para>
3898
3899     <para>
3900      The <function>substring</> function with two parameters,
3901      <function>substring(<replaceable>string</replaceable> from
3902      <replaceable>pattern</replaceable>)</function>, provides extraction of a
3903      substring
3904      that matches a POSIX regular expression pattern.  It returns null if
3905      there is no match, otherwise the portion of the text that matched the
3906      pattern.  But if the pattern contains any parentheses, the portion
3907      of the text that matched the first parenthesized subexpression (the
3908      one whose left parenthesis comes first) is
3909      returned.  You can put parentheses around the whole expression
3910      if you want to use parentheses within it without triggering this
3911      exception.  If you need parentheses in the pattern before the
3912      subexpression you want to extract, see the non-capturing parentheses
3913      described below.
3914     </para>
3915
3916    <para>
3917     Some examples:
3918 <programlisting>
3919 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
3920 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
3921 </programlisting>
3922    </para>
3923
3924     <para>
3925      The <function>regexp_replace</> function provides substitution of
3926      new text for substrings that match POSIX regular expression patterns.
3927      It has the syntax
3928      <function>regexp_replace</function>(<replaceable>source</>,
3929      <replaceable>pattern</>, <replaceable>replacement</>
3930      <optional>, <replaceable>flags</> </optional>).
3931      The <replaceable>source</> string is returned unchanged if
3932      there is no match to the <replaceable>pattern</>.  If there is a
3933      match, the <replaceable>source</> string is returned with the
3934      <replaceable>replacement</> string substituted for the matching
3935      substring.  The <replaceable>replacement</> string can contain
3936      <literal>\</><replaceable>n</>, where <replaceable>n</> is 1
3937      through 9, to indicate that the source substring matching the
3938      <replaceable>n</>'th parenthesized subexpression of the pattern should be
3939      inserted, and it can contain <literal>\&amp;</> to indicate that the
3940      substring matching the entire pattern should be inserted.  Write
3941      <literal>\\</> if you need to put a literal backslash in the replacement
3942      text.
3943      The <replaceable>flags</> parameter is an optional text
3944      string containing zero or more single-letter flags that change the
3945      function's behavior.  Flag <literal>i</> specifies case-insensitive
3946      matching, while flag <literal>g</> specifies replacement of each matching
3947      substring rather than only the first one.  Other supported flags are
3948      described in <xref linkend="posix-embedded-options-table">.
3949     </para>
3950
3951    <para>
3952     Some examples:
3953 <programlisting>
3954 regexp_replace('foobarbaz', 'b..', 'X')
3955                                    <lineannotation>fooXbaz</lineannotation>
3956 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3957                                    <lineannotation>fooXX</lineannotation>
3958 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3959                                    <lineannotation>fooXarYXazY</lineannotation>
3960 </programlisting>
3961    </para>
3962
3963     <para>
3964      The <function>regexp_matches</> function returns a text array of
3965      all of the captured substrings resulting from matching a POSIX
3966      regular expression pattern.  It has the syntax
3967      <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3968      <optional>, <replaceable>flags</> </optional>).
3969      The function can return no rows, one row, or multiple rows (see
3970      the <literal>g</> flag below).  If the <replaceable>pattern</>
3971      does not match, the function returns no rows.  If the pattern
3972      contains no parenthesized subexpressions, then each row
3973      returned is a single-element text array containing the substring
3974      matching the whole pattern.  If the pattern contains parenthesized
3975      subexpressions, the function returns a text array whose
3976      <replaceable>n</>'th element is the substring matching the
3977      <replaceable>n</>'th parenthesized subexpression of the pattern
3978      (not counting <quote>non-capturing</> parentheses; see below for
3979      details).
3980      The <replaceable>flags</> parameter is an optional text
3981      string containing zero or more single-letter flags that change the
3982      function's behavior.  Flag <literal>g</> causes the function to find
3983      each match in the string, not only the first one, and return a row for
3984      each such match.  Other supported
3985      flags are described in <xref linkend="posix-embedded-options-table">.
3986     </para>
3987
3988    <para>
3989     Some examples:
3990 <programlisting>
3991 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3992  regexp_matches 
3993 ----------------
3994  {bar,beque}
3995 (1 row)
3996
3997 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3998  regexp_matches 
3999 ----------------
4000  {bar,beque}
4001  {bazil,barf}
4002 (2 rows)
4003
4004 SELECT regexp_matches('foobarbequebaz', 'barbeque');
4005  regexp_matches 
4006 ----------------
4007  {barbeque}
4008 (1 row)
4009 </programlisting>
4010    </para>
4011
4012    <para>
4013     It is possible to force <function>regexp_matches()</> to always
4014     return one row by using a sub-select;  this is particularly useful
4015     in a <literal>SELECT</> target list when you want all rows
4016     returned, even non-matching ones:
4017 <programlisting>
4018 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
4019 </programlisting>
4020    </para>
4021
4022     <para>
4023      The <function>regexp_split_to_table</> function splits a string using a POSIX
4024      regular expression pattern as a delimiter.  It has the syntax
4025      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
4026      <optional>, <replaceable>flags</> </optional>).
4027      If there is no match to the <replaceable>pattern</>, the function returns the
4028      <replaceable>string</>.  If there is at least one match, for each match it returns
4029      the text from the end of the last match (or the beginning of the string)
4030      to the beginning of the match.  When there are no more matches, it
4031      returns the text from the end of the last match to the end of the string.
4032      The <replaceable>flags</> parameter is an optional text string containing
4033      zero or more single-letter flags that change the function's behavior.
4034      <function>regexp_split_to_table</function> supports the flags described in
4035      <xref linkend="posix-embedded-options-table">.
4036     </para>
4037
4038     <para>
4039      The <function>regexp_split_to_array</> function behaves the same as
4040      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
4041      returns its result as an array of <type>text</>.  It has the syntax
4042      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
4043      <optional>, <replaceable>flags</> </optional>).
4044      The parameters are the same as for <function>regexp_split_to_table</>.
4045     </para>
4046
4047    <para>
4048     Some examples:
4049 <programlisting>
4050
4051 SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', E'\\s+') AS foo;
4052   foo   
4053 -------
4054  the    
4055  quick  
4056  brown  
4057  fox    
4058  jumps 
4059  over   
4060  the    
4061  lazy   
4062  dog    
4063 (9 rows)
4064
4065 SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', E'\\s+');
4066               regexp_split_to_array             
4067 -----------------------------------------------
4068  {the,quick,brown,fox,jumps,over,the,lazy,dog}
4069 (1 row)
4070
4071 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
4072  foo 
4073 -----
4074  t         
4075  h         
4076  e         
4077  q         
4078  u         
4079  i         
4080  c         
4081  k         
4082  b         
4083  r         
4084  o         
4085  w         
4086  n         
4087  f         
4088  o         
4089  x         
4090 (16 rows)
4091 </programlisting>
4092    </para>
4093
4094    <para>
4095     As the last example demonstrates, the regexp split functions ignore
4096     zero-length matches that occur at the start or end of the string
4097     or immediately after a previous match.  This is contrary to the strict
4098     definition of regexp matching that is implemented by
4099     <function>regexp_matches</>, but is usually the most convenient behavior
4100     in practice.  Other software systems such as Perl use similar definitions.
4101    </para>
4102
4103 <!-- derived from the re_syntax.n man page -->
4104
4105    <sect3 id="posix-syntax-details">
4106     <title>Regular Expression Details</title>
4107
4108    <para>
4109     <productname>PostgreSQL</productname>'s regular expressions are implemented
4110     using a software package written by Henry Spencer.  Much of
4111     the description of regular expressions below is copied verbatim from his
4112     manual.
4113    </para>
4114
4115    <para>
4116     Regular expressions (<acronym>RE</acronym>s), as defined in
4117     <acronym>POSIX</acronym> 1003.2, come in two forms:
4118     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
4119     (roughly those of <command>egrep</command>), and
4120     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
4121     (roughly those of <command>ed</command>).
4122     <productname>PostgreSQL</productname> supports both forms, and
4123     also implements some extensions
4124     that are not in the POSIX standard, but have become widely used
4125     due to their availability in programming languages such as Perl and Tcl.
4126     <acronym>RE</acronym>s using these non-POSIX extensions are called
4127     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
4128     in this documentation.  AREs are almost an exact superset of EREs,
4129     but BREs have several notational incompatibilities (as well as being
4130     much more limited).
4131     We first describe the ARE and ERE forms, noting features that apply
4132     only to AREs, and then describe how BREs differ.
4133    </para>
4134
4135    <note>
4136     <para>
4137      <productname>PostgreSQL</> always initially presumes that a regular
4138      expression follows the ARE rules.  However, the more limited ERE or
4139      BRE rules can be chosen by prepending an <firstterm>embedded option</>
4140      to the RE pattern, as described in <xref linkend="posix-metasyntax">.
4141      This can be useful for compatibility with applications that expect
4142      exactly the <acronym>POSIX</acronym> 1003.2 rules.
4143     </para>
4144    </note>
4145
4146    <para>
4147     A regular expression is defined as one or more
4148     <firstterm>branches</firstterm>, separated by
4149     <literal>|</literal>.  It matches anything that matches one of the
4150     branches.
4151    </para>
4152
4153    <para>
4154     A branch is zero or more <firstterm>quantified atoms</> or
4155     <firstterm>constraints</>, concatenated.
4156     It matches a match for the first, followed by a match for the second, etc;
4157     an empty branch matches the empty string.
4158    </para>
4159
4160    <para>
4161     A quantified atom is an <firstterm>atom</> possibly followed
4162     by a single <firstterm>quantifier</>.
4163     Without a quantifier, it matches a match for the atom.
4164     With a quantifier, it can match some number of matches of the atom.
4165     An <firstterm>atom</firstterm> can be any of the possibilities
4166     shown in <xref linkend="posix-atoms-table">.
4167     The possible quantifiers and their meanings are shown in
4168     <xref linkend="posix-quantifiers-table">.
4169    </para>
4170
4171    <para>
4172     A <firstterm>constraint</> matches an empty string, but matches only when
4173     specific conditions are met.  A constraint can be used where an atom
4174     could be used, except it cannot be followed by a quantifier.
4175     The simple constraints are shown in
4176     <xref linkend="posix-constraints-table">;
4177     some more constraints are described later.
4178    </para>
4179
4180
4181    <table id="posix-atoms-table">
4182     <title>Regular Expression Atoms</title>
4183
4184     <tgroup cols="2">
4185      <thead>
4186       <row>
4187        <entry>Atom</entry>
4188        <entry>Description</entry>
4189       </row>
4190      </thead>
4191
4192       <tbody>
4193        <row>
4194        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
4195        <entry> (where <replaceable>re</> is any regular expression)
4196        matches a match for
4197        <replaceable>re</>, with the match noted for possible reporting </entry>
4198        </row>
4199
4200        <row>
4201        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
4202        <entry> as above, but the match is not noted for reporting
4203        (a <quote>non-capturing</> set of parentheses)
4204        (AREs only) </entry>
4205        </row>
4206
4207        <row>
4208        <entry> <literal>.</> </entry>
4209        <entry> matches any single character </entry>
4210        </row>
4211
4212        <row>
4213        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
4214        <entry> a <firstterm>bracket expression</>,
4215        matching any one of the <replaceable>chars</> (see
4216        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
4217        </row>
4218
4219        <row>
4220        <entry> <literal>\</><replaceable>k</> </entry>
4221        <entry> (where <replaceable>k</> is a non-alphanumeric character)
4222        matches that character taken as an ordinary character,
4223        e.g., <literal>\\</> matches a backslash character </entry>
4224        </row>
4225
4226        <row>
4227        <entry> <literal>\</><replaceable>c</> </entry>
4228        <entry> where <replaceable>c</> is alphanumeric
4229        (possibly followed by other characters)
4230        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
4231        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
4232        </row>
4233
4234        <row>
4235        <entry> <literal>{</> </entry>
4236        <entry> when followed by a character other than a digit,
4237        matches the left-brace character <literal>{</>;
4238        when followed by a digit, it is the beginning of a
4239        <replaceable>bound</> (see below) </entry>
4240        </row>
4241
4242        <row>
4243        <entry> <replaceable>x</> </entry>
4244        <entry> where <replaceable>x</> is a single character with no other
4245        significance, matches that character </entry>
4246        </row>
4247       </tbody>
4248      </tgroup>
4249     </table>
4250
4251    <para>
4252     An RE cannot end with a backslash (<literal>\</>).
4253    </para>
4254
4255    <note>
4256     <para>
4257      If you have <xref linkend="guc-standard-conforming-strings"> turned off,
4258      any backslashes you write in literal string constants will need to be
4259      doubled.  See <xref linkend="sql-syntax-strings"> for more information.
4260     </para>
4261    </note>
4262
4263    <table id="posix-quantifiers-table">
4264     <title>Regular Expression Quantifiers</title>
4265
4266     <tgroup cols="2">
4267      <thead>
4268       <row>
4269        <entry>Quantifier</entry>
4270        <entry>Matches</entry>
4271       </row>
4272      </thead>
4273
4274       <tbody>
4275        <row>
4276        <entry> <literal>*</> </entry>
4277        <entry> a sequence of 0 or more matches of the atom </entry>
4278        </row>
4279
4280        <row>
4281        <entry> <literal>+</> </entry>
4282        <entry> a sequence of 1 or more matches of the atom </entry>
4283        </row>
4284
4285        <row>
4286        <entry> <literal>?</> </entry>
4287        <entry> a sequence of 0 or 1 matches of the atom </entry>
4288        </row>
4289
4290        <row>
4291        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
4292        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
4293        </row>
4294
4295        <row>
4296        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
4297        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
4298        </row>
4299
4300        <row>
4301        <entry>
4302        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4303        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
4304        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
4305        <replaceable>n</> </entry>
4306        </row>
4307
4308        <row>
4309        <entry> <literal>*?</> </entry>
4310        <entry> non-greedy version of <literal>*</> </entry>
4311        </row>
4312
4313        <row>
4314        <entry> <literal>+?</> </entry>
4315        <entry> non-greedy version of <literal>+</> </entry>
4316        </row>
4317
4318        <row>
4319        <entry> <literal>??</> </entry>
4320        <entry> non-greedy version of <literal>?</> </entry>
4321        </row>
4322
4323        <row>
4324        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
4325        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
4326        </row>
4327
4328        <row>
4329        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
4330        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
4331        </row>
4332
4333        <row>
4334        <entry>
4335        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
4336        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4337        </row>
4338       </tbody>
4339      </tgroup>
4340     </table>
4341
4342    <para>
4343     The forms using <literal>{</><replaceable>...</><literal>}</>
4344     are known as <firstterm>bounds</>.
4345     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
4346     unsigned decimal integers with permissible values from 0 to 255 inclusive.
4347    </para>
4348
4349     <para>
4350      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
4351      same possibilities as their corresponding normal (<firstterm>greedy</>)
4352      counterparts, but prefer the smallest number rather than the largest
4353      number of matches.
4354      See <xref linkend="posix-matching-rules"> for more detail.
4355    </para>
4356
4357    <note>
4358     <para>
4359      A quantifier cannot immediately follow another quantifier, e.g.,
4360      <literal>**</> is invalid.
4361      A quantifier cannot
4362      begin an expression or subexpression or follow
4363      <literal>^</literal> or <literal>|</literal>.
4364     </para>
4365    </note>
4366
4367    <table id="posix-constraints-table">
4368     <title>Regular Expression Constraints</title>
4369
4370     <tgroup cols="2">
4371      <thead>
4372       <row>
4373        <entry>Constraint</entry>
4374        <entry>Description</entry>
4375       </row>
4376      </thead>
4377
4378       <tbody>
4379        <row>
4380        <entry> <literal>^</> </entry>
4381        <entry> matches at the beginning of the string </entry>
4382        </row>
4383
4384        <row>
4385        <entry> <literal>$</> </entry>
4386        <entry> matches at the end of the string </entry>
4387        </row>
4388
4389        <row>
4390        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
4391        <entry> <firstterm>positive lookahead</> matches at any point
4392        where a substring matching <replaceable>re</> begins
4393        (AREs only) </entry>
4394        </row>
4395
4396        <row>
4397        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
4398        <entry> <firstterm>negative lookahead</> matches at any point
4399        where no substring matching <replaceable>re</> begins
4400        (AREs only) </entry>
4401        </row>
4402       </tbody>
4403      </tgroup>
4404     </table>
4405
4406    <para>
4407     Lookahead constraints cannot contain <firstterm>back references</>
4408     (see <xref linkend="posix-escape-sequences">),
4409     and all parentheses within them are considered non-capturing.
4410    </para>
4411    </sect3>
4412
4413    <sect3 id="posix-bracket-expressions">
4414     <title>Bracket Expressions</title>
4415
4416    <para>
4417     A <firstterm>bracket expression</firstterm> is a list of
4418     characters enclosed in <literal>[]</literal>.  It normally matches
4419     any single character from the list (but see below).  If the list
4420     begins with <literal>^</literal>, it matches any single character
4421     <emphasis>not</> from the rest of the list.
4422     If two characters
4423     in the list are separated by <literal>-</literal>, this is
4424     shorthand for the full range of characters between those two
4425     (inclusive) in the collating sequence,
4426     e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
4427     any decimal digit.  It is illegal for two ranges to share an
4428     endpoint, e.g.,  <literal>a-c-e</literal>.  Ranges are very
4429     collating-sequence-dependent, so portable programs should avoid
4430     relying on them.
4431    </para>
4432
4433    <para>
4434     To include a literal <literal>]</literal> in the list, make it the
4435     first character (after <literal>^</literal>, if that is used).  To
4436     include a literal <literal>-</literal>, make it the first or last
4437     character, or the second endpoint of a range.  To use a literal
4438     <literal>-</literal> as the first endpoint of a range, enclose it
4439     in <literal>[.</literal> and <literal>.]</literal> to make it a
4440     collating element (see below).  With the exception of these characters,
4441     some combinations using <literal>[</literal>
4442     (see next paragraphs), and escapes (AREs only), all other special
4443     characters lose their special significance within a bracket expression.
4444     In particular, <literal>\</literal> is not special when following
4445     ERE or BRE rules, though it is special (as introducing an escape)
4446     in AREs.
4447    </para>
4448
4449    <para>
4450     Within a bracket expression, a collating element (a character, a
4451     multiple-character sequence that collates as if it were a single
4452     character, or a collating-sequence name for either) enclosed in
4453     <literal>[.</literal> and <literal>.]</literal> stands for the
4454     sequence of characters of that collating element.  The sequence is
4455     treated as a single element of the bracket expression's list.  This
4456     allows a bracket
4457     expression containing a multiple-character collating element to
4458     match more than one character, e.g., if the collating sequence
4459     includes a <literal>ch</literal> collating element, then the RE
4460     <literal>[[.ch.]]*c</literal> matches the first five characters of
4461     <literal>chchcc</literal>.
4462    </para>
4463
4464    <note>
4465     <para>
4466      <productname>PostgreSQL</> currently does not support multi-character collating
4467      elements. This information describes possible future behavior.
4468     </para>
4469    </note>
4470
4471    <para>
4472     Within a bracket expression, a collating element enclosed in
4473     <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
4474     class</>, standing for the sequences of characters of all collating
4475     elements equivalent to that one, including itself.  (If there are
4476     no other equivalent collating elements, the treatment is as if the
4477     enclosing delimiters were <literal>[.</literal> and
4478     <literal>.]</literal>.)  For example, if <literal>o</literal> and
4479     <literal>^</literal> are the members of an equivalence class, then
4480     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
4481     <literal>[o^]</literal> are all synonymous.  An equivalence class
4482     cannot be an endpoint of a range.
4483    </para>
4484
4485    <para>
4486     Within a bracket expression, the name of a character class
4487     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
4488     for the list of all characters belonging to that class.  Standard
4489     character class names are: <literal>alnum</literal>,
4490     <literal>alpha</literal>, <literal>blank</literal>,
4491     <literal>cntrl</literal>, <literal>digit</literal>,
4492     <literal>graph</literal>, <literal>lower</literal>,
4493     <literal>print</literal>, <literal>punct</literal>,
4494     <literal>space</literal>, <literal>upper</literal>,
4495     <literal>xdigit</literal>.  These stand for the character classes
4496     defined in
4497     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
4498     A locale can provide others.  A character class cannot be used as
4499     an endpoint of a range.
4500    </para>
4501
4502    <para>
4503     There are two special cases of bracket expressions:  the bracket
4504     expressions <literal>[[:&lt;:]]</literal> and
4505     <literal>[[:&gt;:]]</literal> are constraints,
4506     matching empty strings at the beginning
4507     and end of a word respectively.  A word is defined as a sequence
4508     of word characters that is neither preceded nor followed by word
4509     characters.  A word character is an <literal>alnum</> character (as
4510     defined by
4511     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
4512     or an underscore.  This is an extension, compatible with but not
4513     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
4514     caution in software intended to be portable to other systems.
4515     The constraint escapes described below are usually preferable; they
4516     are no more standard, but are easier to type.
4517    </para>
4518    </sect3>
4519
4520    <sect3 id="posix-escape-sequences">
4521     <title>Regular Expression Escapes</title>
4522
4523    <para>
4524     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
4525     followed by an alphanumeric character. Escapes come in several varieties:
4526     character entry, class shorthands, constraint escapes, and back references.
4527     A <literal>\</> followed by an alphanumeric character but not constituting
4528     a valid escape is illegal in AREs.
4529     In EREs, there are no escapes: outside a bracket expression,
4530     a <literal>\</> followed by an alphanumeric character merely stands for
4531     that character as an ordinary character, and inside a bracket expression,
4532     <literal>\</> is an ordinary character.
4533     (The latter is the one actual incompatibility between EREs and AREs.)
4534    </para>
4535
4536    <para>
4537     <firstterm>Character-entry escapes</> exist to make it easier to specify
4538     non-printing and other inconvenient characters in REs.  They are
4539     shown in <xref linkend="posix-character-entry-escapes-table">.
4540    </para>
4541
4542    <para>
4543     <firstterm>Class-shorthand escapes</> provide shorthands for certain
4544     commonly-used character classes.  They are
4545     shown in <xref linkend="posix-class-shorthand-escapes-table">.
4546    </para>
4547
4548    <para>
4549     A <firstterm>constraint escape</> is a constraint,
4550     matching the empty string if specific conditions are met,
4551     written as an escape.  They are
4552     shown in <xref linkend="posix-constraint-escapes-table">.
4553    </para>
4554
4555    <para>
4556     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
4557     same string matched by the previous parenthesized subexpression specified
4558     by the number <replaceable>n</>
4559     (see <xref linkend="posix-constraint-backref-table">).  For example,
4560     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
4561     but not <literal>bc</> or <literal>cb</>.
4562     The subexpression must entirely precede the back reference in the RE.
4563     Subexpressions are numbered in the order of their leading parentheses.
4564     Non-capturing parentheses do not define subexpressions.
4565    </para>
4566
4567    <note>
4568     <para>
4569      Keep in mind that an escape's leading <literal>\</> will need to be
4570      doubled when entering the pattern as an SQL string constant.  For example:
4571 <programlisting>
4572 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
4573 </programlisting>
4574     </para>
4575    </note>
4576
4577    <table id="posix-character-entry-escapes-table">
4578     <title>Regular Expression Character-entry Escapes</title>
4579
4580     <tgroup cols="2">
4581      <thead>
4582       <row>
4583        <entry>Escape</entry>
4584        <entry>Description</entry>
4585       </row>
4586      </thead>
4587
4588       <tbody>
4589        <row>
4590        <entry> <literal>\a</> </entry>
4591        <entry> alert (bell) character, as in C </entry>
4592        </row>
4593
4594        <row>
4595        <entry> <literal>\b</> </entry>
4596        <entry> backspace, as in C </entry>
4597        </row>
4598
4599        <row>
4600        <entry> <literal>\B</> </entry>
4601        <entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
4602        doubling </entry>
4603        </row>
4604
4605        <row>
4606        <entry> <literal>\c</><replaceable>X</> </entry>
4607        <entry> (where <replaceable>X</> is any character) the character whose
4608        low-order 5 bits are the same as those of
4609        <replaceable>X</>, and whose other bits are all zero </entry>
4610        </row>
4611
4612        <row>
4613        <entry> <literal>\e</> </entry>
4614        <entry> the character whose collating-sequence name
4615        is <literal>ESC</>,
4616        or failing that, the character with octal value 033 </entry>
4617        </row>
4618
4619        <row>
4620        <entry> <literal>\f</> </entry>
4621        <entry> form feed, as in C </entry>
4622        </row>
4623
4624        <row>
4625        <entry> <literal>\n</> </entry>
4626        <entry> newline, as in C </entry>
4627        </row>
4628
4629        <row>
4630        <entry> <literal>\r</> </entry>
4631        <entry> carriage return, as in C </entry>
4632        </row>
4633
4634        <row>
4635        <entry> <literal>\t</> </entry>
4636        <entry> horizontal tab, as in C </entry>
4637        </row>
4638
4639        <row>
4640        <entry> <literal>\u</><replaceable>wxyz</> </entry>
4641        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4642        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4643        in the local byte ordering </entry>
4644        </row>
4645
4646        <row>
4647        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4648        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4649        digits)
4650        reserved for a hypothetical Unicode extension to 32 bits
4651        </entry>
4652        </row>
4653
4654        <row>
4655        <entry> <literal>\v</> </entry>
4656        <entry> vertical tab, as in C </entry>
4657        </row>
4658
4659        <row>
4660        <entry> <literal>\x</><replaceable>hhh</> </entry>
4661        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4662        digits)
4663        the character whose hexadecimal value is
4664        <literal>0x</><replaceable>hhh</>
4665        (a single character no matter how many hexadecimal digits are used)
4666        </entry>
4667        </row>
4668
4669        <row>
4670        <entry> <literal>\0</> </entry>
4671        <entry> the character whose value is <literal>0</> (the null byte)</entry>
4672        </row>
4673
4674        <row>
4675        <entry> <literal>\</><replaceable>xy</> </entry>
4676        <entry> (where <replaceable>xy</> is exactly two octal digits,
4677        and is not a <firstterm>back reference</>)
4678        the character whose octal value is
4679        <literal>0</><replaceable>xy</> </entry>
4680        </row>
4681
4682        <row>
4683        <entry> <literal>\</><replaceable>xyz</> </entry>
4684        <entry> (where <replaceable>xyz</> is exactly three octal digits,
4685        and is not a <firstterm>back reference</>)
4686        the character whose octal value is
4687        <literal>0</><replaceable>xyz</> </entry>
4688        </row>
4689       </tbody>
4690      </tgroup>
4691     </table>
4692
4693    <para>
4694     Hexadecimal digits are <literal>0</>-<literal>9</>,
4695     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4696     Octal digits are <literal>0</>-<literal>7</>.
4697    </para>
4698
4699    <para>
4700     The character-entry escapes are always taken as ordinary characters.
4701     For example, <literal>\135</> is <literal>]</> in ASCII, but
4702     <literal>\135</> does not terminate a bracket expression.
4703    </para>
4704
4705    <table id="posix-class-shorthand-escapes-table">
4706     <title>Regular Expression Class-shorthand Escapes</title>
4707
4708     <tgroup cols="2">
4709      <thead>
4710       <row>
4711        <entry>Escape</entry>
4712        <entry>Description</entry>
4713       </row>
4714      </thead>
4715
4716       <tbody>
4717        <row>
4718        <entry> <literal>\d</> </entry>
4719        <entry> <literal>[[:digit:]]</> </entry>
4720        </row>
4721
4722        <row>
4723        <entry> <literal>\s</> </entry>
4724        <entry> <literal>[[:space:]]</> </entry>
4725        </row>
4726
4727        <row>
4728        <entry> <literal>\w</> </entry>
4729        <entry> <literal>[[:alnum:]_]</>
4730        (note underscore is included) </entry>
4731        </row>
4732
4733        <row>
4734        <entry> <literal>\D</> </entry>
4735        <entry> <literal>[^[:digit:]]</> </entry>
4736        </row>
4737
4738        <row>
4739        <entry> <literal>\S</> </entry>
4740        <entry> <literal>[^[:space:]]</> </entry>
4741        </row>
4742
4743        <row>
4744        <entry> <literal>\W</> </entry>
4745        <entry> <literal>[^[:alnum:]_]</>
4746        (note underscore is included) </entry>
4747        </row>
4748       </tbody>
4749      </tgroup>
4750     </table>
4751
4752    <para>
4753     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4754     and <literal>\w</> lose their outer brackets,
4755     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4756     (So, for example, <literal>[a-c\d]</> is equivalent to
4757     <literal>[a-c[:digit:]]</>.
4758     Also, <literal>[a-c\D]</>, which is equivalent to
4759     <literal>[a-c^[:digit:]]</>, is illegal.)
4760    </para>
4761
4762    <table id="posix-constraint-escapes-table">
4763     <title>Regular Expression Constraint Escapes</title>
4764
4765     <tgroup cols="2">
4766      <thead>
4767       <row>
4768        <entry>Escape</entry>
4769        <entry>Description</entry>
4770       </row>
4771      </thead>
4772
4773       <tbody>
4774        <row>
4775        <entry> <literal>\A</> </entry>
4776        <entry> matches only at the beginning of the string
4777        (see <xref linkend="posix-matching-rules"> for how this differs from
4778        <literal>^</>) </entry>
4779        </row>
4780
4781        <row>
4782        <entry> <literal>\m</> </entry>
4783        <entry> matches only at the beginning of a word </entry>
4784        </row>
4785
4786        <row>
4787        <entry> <literal>\M</> </entry>
4788        <entry> matches only at the end of a word </entry>
4789        </row>
4790
4791        <row>
4792        <entry> <literal>\y</> </entry>
4793        <entry> matches only at the beginning or end of a word </entry>
4794        </row>
4795
4796        <row>
4797        <entry> <literal>\Y</> </entry>
4798        <entry> matches only at a point that is not the beginning or end of a
4799        word </entry>
4800        </row>
4801
4802        <row>
4803        <entry> <literal>\Z</> </entry>
4804        <entry> matches only at the end of the string
4805        (see <xref linkend="posix-matching-rules"> for how this differs from
4806        <literal>$</>) </entry>
4807        </row>
4808       </tbody>
4809      </tgroup>
4810     </table>
4811
4812    <para>
4813     A word is defined as in the specification of
4814     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4815     Constraint escapes are illegal within bracket expressions.
4816    </para>
4817
4818    <table id="posix-constraint-backref-table">
4819     <title>Regular Expression Back References</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>\</><replaceable>m</> </entry>
4832        <entry> (where <replaceable>m</> is a nonzero digit)
4833        a back reference to the <replaceable>m</>'th subexpression </entry>
4834        </row>
4835
4836        <row>
4837        <entry> <literal>\</><replaceable>mnn</> </entry>
4838        <entry> (where <replaceable>m</> is a nonzero digit, and
4839        <replaceable>nn</> is some more digits, and the decimal value
4840        <replaceable>mnn</> is not greater than the number of closing capturing
4841        parentheses seen so far)
4842        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4843        </row>
4844       </tbody>
4845      </tgroup>
4846     </table>
4847
4848    <note>
4849     <para>
4850      There is an inherent ambiguity between octal character-entry
4851      escapes and back references, which is resolved by the following heuristics,
4852      as hinted at above.
4853      A leading zero always indicates an octal escape.
4854      A single non-zero digit, not followed by another digit,
4855      is always taken as a back reference.
4856      A multi-digit sequence not starting with a zero is taken as a back
4857      reference if it comes after a suitable subexpression
4858      (i.e., the number is in the legal range for a back reference),
4859      and otherwise is taken as octal.
4860     </para>
4861    </note>
4862    </sect3>
4863
4864    <sect3 id="posix-metasyntax">
4865     <title>Regular Expression Metasyntax</title>
4866
4867    <para>
4868     In addition to the main syntax described above, there are some special
4869     forms and miscellaneous syntactic facilities available.
4870    </para>
4871
4872    <para>
4873     An RE can begin with one of two special <firstterm>director</> prefixes.
4874     If an RE begins with <literal>***:</>,
4875     the rest of the RE is taken as an ARE.  (This normally has no effect in
4876     <productname>PostgreSQL</>, since REs are assumed to be AREs;
4877     but it does have an effect if ERE or BRE mode had been specified by
4878     the <replaceable>flags</> parameter to a regex function.)
4879     If an RE begins with <literal>***=</>,
4880     the rest of the RE is taken to be a literal string,
4881     with all characters considered ordinary characters.
4882    </para>
4883
4884    <para>
4885     An ARE can begin with <firstterm>embedded options</>:
4886     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4887     (where <replaceable>xyz</> is one or more alphabetic characters)
4888     specifies options affecting the rest of the RE.
4889     These options override any previously determined options &mdash;
4890     in particular, they can override the case-sensitivity behavior implied by
4891     a regex operator, or the <replaceable>flags</> parameter to a regex
4892     function.
4893     The available option letters are
4894     shown in <xref linkend="posix-embedded-options-table">.
4895     Note that these same option letters are used in the <replaceable>flags</>
4896     parameters of regex functions.
4897    </para>
4898
4899    <table id="posix-embedded-options-table">
4900     <title>ARE Embedded-option Letters</title>
4901
4902     <tgroup cols="2">
4903      <thead>
4904       <row>
4905        <entry>Option</entry>
4906        <entry>Description</entry>
4907       </row>
4908      </thead>
4909
4910       <tbody>
4911        <row>
4912        <entry> <literal>b</> </entry>
4913        <entry> rest of RE is a BRE </entry>
4914        </row>
4915
4916        <row>
4917        <entry> <literal>c</> </entry>
4918        <entry> case-sensitive matching (overrides operator type) </entry>
4919        </row>
4920
4921        <row>
4922        <entry> <literal>e</> </entry>
4923        <entry> rest of RE is an ERE </entry>
4924        </row>
4925
4926        <row>
4927        <entry> <literal>i</> </entry>
4928        <entry> case-insensitive matching (see
4929        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4930        </row>
4931
4932        <row>
4933        <entry> <literal>m</> </entry>
4934        <entry> historical synonym for <literal>n</> </entry>
4935        </row>
4936
4937        <row>
4938        <entry> <literal>n</> </entry>
4939        <entry> newline-sensitive matching (see
4940        <xref linkend="posix-matching-rules">) </entry>
4941        </row>
4942
4943        <row>
4944        <entry> <literal>p</> </entry>
4945        <entry> partial newline-sensitive matching (see
4946        <xref linkend="posix-matching-rules">) </entry>
4947        </row>
4948
4949        <row>
4950        <entry> <literal>q</> </entry>
4951        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4952        characters </entry>
4953        </row>
4954
4955        <row>
4956        <entry> <literal>s</> </entry>
4957        <entry> non-newline-sensitive matching (default) </entry>
4958        </row>
4959
4960        <row>
4961        <entry> <literal>t</> </entry>
4962        <entry> tight syntax (default; see below) </entry>
4963        </row>
4964
4965        <row>
4966        <entry> <literal>w</> </entry>
4967        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4968        (see <xref linkend="posix-matching-rules">) </entry>
4969        </row>
4970
4971        <row>
4972        <entry> <literal>x</> </entry>
4973        <entry> expanded syntax (see below) </entry>
4974        </row>
4975       </tbody>
4976      </tgroup>
4977     </table>
4978
4979    <para>
4980     Embedded options take effect at the <literal>)</> terminating the sequence.
4981     They can appear only at the start of an ARE (after the
4982     <literal>***:</> director if any).
4983    </para>
4984
4985    <para>
4986     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4987     characters are significant, there is an <firstterm>expanded</> syntax,
4988     available by specifying the embedded <literal>x</> option.
4989     In the expanded syntax,
4990     white-space characters in the RE are ignored, as are
4991     all characters between a <literal>#</>
4992     and the following newline (or the end of the RE).  This
4993     permits paragraphing and commenting a complex RE.
4994     There are three exceptions to that basic rule:
4995
4996     <itemizedlist>
4997      <listitem>
4998       <para>
4999        a white-space character or <literal>#</> preceded by <literal>\</> is
5000        retained
5001       </para>
5002      </listitem>
5003      <listitem>
5004       <para>
5005        white space or <literal>#</> within a bracket expression is retained
5006       </para>
5007      </listitem>
5008      <listitem>
5009       <para>
5010        white space and comments cannot appear within multi-character symbols,
5011        such as <literal>(?:</>
5012       </para>
5013      </listitem>
5014     </itemizedlist>
5015
5016     For this purpose, white-space characters are blank, tab, newline, and
5017     any character that belongs to the <replaceable>space</> character class.
5018    </para>
5019
5020    <para>
5021     Finally, in an ARE, outside bracket expressions, the sequence
5022     <literal>(?#</><replaceable>ttt</><literal>)</>
5023     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
5024     is a comment, completely ignored.
5025     Again, this is not allowed between the characters of
5026     multi-character symbols, like <literal>(?:</>.
5027     Such comments are more a historical artifact than a useful facility,
5028     and their use is deprecated; use the expanded syntax instead.
5029    </para>
5030
5031    <para>
5032     <emphasis>None</> of these metasyntax extensions is available if
5033     an initial <literal>***=</> director
5034     has specified that the user's input be treated as a literal string
5035     rather than as an RE.
5036    </para>
5037    </sect3>
5038
5039    <sect3 id="posix-matching-rules">
5040     <title>Regular Expression Matching Rules</title>
5041
5042    <para>
5043     In the event that an RE could match more than one substring of a given
5044     string, the RE matches the one starting earliest in the string.
5045     If the RE could match more than one substring starting at that point,
5046     either the longest possible match or the shortest possible match will
5047     be taken, depending on whether the RE is <firstterm>greedy</> or
5048     <firstterm>non-greedy</>.
5049    </para>
5050
5051    <para>
5052     Whether an RE is greedy or not is determined by the following rules:
5053     <itemizedlist>
5054      <listitem>
5055       <para>
5056        Most atoms, and all constraints, have no greediness attribute (because
5057        they cannot match variable amounts of text anyway).
5058       </para>
5059      </listitem>
5060      <listitem>
5061       <para>
5062        Adding parentheses around an RE does not change its greediness.
5063       </para>
5064      </listitem>
5065      <listitem>
5066       <para>
5067        A quantified atom with a fixed-repetition quantifier
5068        (<literal>{</><replaceable>m</><literal>}</>
5069        or
5070        <literal>{</><replaceable>m</><literal>}?</>)
5071        has the same greediness (possibly none) as the atom itself.
5072       </para>
5073      </listitem>
5074      <listitem>
5075       <para>
5076        A quantified atom with other normal quantifiers (including
5077        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
5078        with <replaceable>m</> equal to <replaceable>n</>)
5079        is greedy (prefers longest match).
5080       </para>
5081      </listitem>
5082      <listitem>
5083       <para>
5084        A quantified atom with a non-greedy quantifier (including
5085        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
5086        with <replaceable>m</> equal to <replaceable>n</>)
5087        is non-greedy (prefers shortest match).
5088       </para>
5089      </listitem>
5090      <listitem>
5091       <para>
5092        A branch &mdash; that is, an RE that has no top-level
5093        <literal>|</> operator &mdash; has the same greediness as the first
5094        quantified atom in it that has a greediness attribute.
5095       </para>
5096      </listitem>
5097      <listitem>
5098       <para>
5099        An RE consisting of two or more branches connected by the
5100        <literal>|</> operator is always greedy.
5101       </para>
5102      </listitem>
5103     </itemizedlist>
5104    </para>
5105
5106    <para>
5107     The above rules associate greediness attributes not only with individual
5108     quantified atoms, but with branches and entire REs that contain quantified
5109     atoms.  What that means is that the matching is done in such a way that
5110     the branch, or whole RE, matches the longest or shortest possible
5111     substring <emphasis>as a whole</>.  Once the length of the entire match
5112     is determined, the part of it that matches any particular subexpression
5113     is determined on the basis of the greediness attribute of that
5114     subexpression, with subexpressions starting earlier in the RE taking
5115     priority over ones starting later.
5116    </para>
5117
5118    <para>
5119     An example of what this means:
5120 <screen>
5121 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
5122 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
5123 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
5124 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
5125 </screen>
5126     In the first case, the RE as a whole is greedy because <literal>Y*</>
5127     is greedy.  It can match beginning at the <literal>Y</>, and it matches
5128     the longest possible string starting there, i.e., <literal>Y123</>.
5129     The output is the parenthesized part of that, or <literal>123</>.
5130     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
5131     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
5132     the shortest possible string starting there, i.e., <literal>Y1</>.
5133     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
5134     the decision as to the overall match length; so it is forced to match
5135     just <literal>1</>.
5136    </para>
5137
5138    <para>
5139     In short, when an RE contains both greedy and non-greedy subexpressions,
5140     the total match length is either as long as possible or as short as
5141     possible, according to the attribute assigned to the whole RE.  The
5142     attributes assigned to the subexpressions only affect how much of that
5143     match they are allowed to <quote>eat</> relative to each other.
5144    </para>
5145
5146    <para>
5147     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
5148     can be used to force greediness or non-greediness, respectively,
5149     on a subexpression or a whole RE.
5150    </para>
5151
5152    <para>
5153     Match lengths are measured in characters, not collating elements.
5154     An empty string is considered longer than no match at all.
5155     For example:
5156     <literal>bb*</>
5157     matches the three middle characters of <literal>abbbc</>;
5158     <literal>(week|wee)(night|knights)</>
5159     matches all ten characters of <literal>weeknights</>;
5160     when <literal>(.*).*</>
5161     is matched against <literal>abc</> the parenthesized subexpression
5162     matches all three characters; and when
5163     <literal>(a*)*</> is matched against <literal>bc</>
5164     both the whole RE and the parenthesized
5165     subexpression match an empty string.
5166    </para>
5167
5168    <para>
5169     If case-independent matching is specified,
5170     the effect is much as if all case distinctions had vanished from the
5171     alphabet.
5172     When an alphabetic that exists in multiple cases appears as an
5173     ordinary character outside a bracket expression, it is effectively
5174     transformed into a bracket expression containing both cases,
5175     e.g., <literal>x</> becomes <literal>[xX]</>.
5176     When it appears inside a bracket expression, all case counterparts
5177     of it are added to the bracket expression, e.g.,
5178     <literal>[x]</> becomes <literal>[xX]</>
5179     and <literal>[^x]</> becomes <literal>[^xX]</>.
5180    </para>
5181
5182    <para>
5183     If newline-sensitive matching is specified, <literal>.</>
5184     and bracket expressions using <literal>^</>
5185     will never match the newline character
5186     (so that matches will never cross newlines unless the RE
5187     explicitly arranges it)
5188     and <literal>^</> and <literal>$</>
5189     will match the empty string after and before a newline
5190     respectively, in addition to matching at beginning and end of string
5191     respectively.
5192     But the ARE escapes <literal>\A</> and <literal>\Z</>
5193     continue to match beginning or end of string <emphasis>only</>.
5194    </para>
5195
5196    <para>
5197     If partial newline-sensitive matching is specified,
5198     this affects <literal>.</> and bracket expressions
5199     as with newline-sensitive matching, but not <literal>^</>
5200     and <literal>$</>.
5201    </para>
5202
5203    <para>
5204     If inverse partial newline-sensitive matching is specified,
5205     this affects <literal>^</> and <literal>$</>
5206     as with newline-sensitive matching, but not <literal>.</>
5207     and bracket expressions.
5208     This isn't very useful but is provided for symmetry.
5209    </para>
5210    </sect3>
5211
5212    <sect3 id="posix-limits-compatibility">
5213     <title>Limits and Compatibility</title>
5214
5215    <para>
5216     No particular limit is imposed on the length of REs in this
5217     implementation.  However,
5218     programs intended to be highly portable should not employ REs longer
5219     than 256 bytes,
5220     as a POSIX-compliant implementation can refuse to accept such REs.
5221    </para>
5222
5223    <para>
5224     The only feature of AREs that is actually incompatible with
5225     POSIX EREs is that <literal>\</> does not lose its special
5226     significance inside bracket expressions.
5227     All other ARE features use syntax which is illegal or has
5228     undefined or unspecified effects in POSIX EREs;
5229     the <literal>***</> syntax of directors likewise is outside the POSIX
5230     syntax for both BREs and EREs.
5231    </para>
5232
5233    <para>
5234     Many of the ARE extensions are borrowed from Perl, but some have
5235     been changed to clean them up, and a few Perl extensions are not present.
5236     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
5237     the lack of special treatment for a trailing newline,
5238     the addition of complemented bracket expressions to the things
5239     affected by newline-sensitive matching,
5240     the restrictions on parentheses and back references in lookahead
5241     constraints, and the longest/shortest-match (rather than first-match)
5242     matching semantics.
5243    </para>
5244
5245    <para>
5246     Two significant incompatibilities exist between AREs and the ERE syntax
5247     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
5248
5249     <itemizedlist>
5250      <listitem>
5251       <para>
5252        In AREs, <literal>\</> followed by an alphanumeric character is either
5253        an escape or an error, while in previous releases, it was just another
5254        way of writing the alphanumeric.
5255        This should not be much of a problem because there was no reason to
5256        write such a sequence in earlier releases.
5257       </para>
5258      </listitem>
5259      <listitem>
5260       <para>
5261        In AREs, <literal>\</> remains a special character within
5262        <literal>[]</>, so a literal <literal>\</> within a bracket
5263        expression must be written <literal>\\</>.
5264       </para>
5265      </listitem>
5266     </itemizedlist>
5267    </para>
5268    </sect3>
5269
5270    <sect3 id="posix-basic-regexes">
5271     <title>Basic Regular Expressions</title>
5272
5273    <para>
5274     BREs differ from EREs in several respects.
5275     In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
5276     are ordinary characters and there is no equivalent
5277     for their functionality.
5278     The delimiters for bounds are
5279     <literal>\{</> and <literal>\}</>,
5280     with <literal>{</> and <literal>}</>
5281     by themselves ordinary characters.
5282     The parentheses for nested subexpressions are
5283     <literal>\(</> and <literal>\)</>,
5284     with <literal>(</> and <literal>)</> by themselves ordinary characters.
5285     <literal>^</> is an ordinary character except at the beginning of the
5286     RE or the beginning of a parenthesized subexpression,
5287     <literal>$</> is an ordinary character except at the end of the
5288     RE or the end of a parenthesized subexpression,
5289     and <literal>*</> is an ordinary character if it appears at the beginning
5290     of the RE or the beginning of a parenthesized subexpression
5291     (after a possible leading <literal>^</>).
5292     Finally, single-digit back references are available, and
5293     <literal>\&lt;</> and <literal>\&gt;</>
5294     are synonyms for
5295     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
5296     respectively; no other escapes are available in BREs.
5297    </para>
5298    </sect3>
5299
5300 <!-- end re_syntax.n man page -->
5301
5302   </sect2>
5303  </sect1>
5304
5305
5306   <sect1 id="functions-formatting">
5307    <title>Data Type Formatting Functions</title>
5308
5309    <indexterm>
5310     <primary>formatting</primary>
5311    </indexterm>
5312
5313    <para>
5314     The <productname>PostgreSQL</productname> formatting functions
5315     provide a powerful set of tools for converting various data types
5316     (date/time, integer, floating point, numeric) to formatted strings
5317     and for converting from formatted strings to specific data types.
5318     <xref linkend="functions-formatting-table"> lists them.
5319     These functions all follow a common calling convention: the first
5320     argument is the value to be formatted and the second argument is a
5321     template that defines the output or input format.
5322    </para>
5323    <para>
5324     A single-argument <function>to_timestamp</function> function is also
5325     available;  it accepts a
5326     <type>double precision</type> argument and converts from Unix epoch
5327     (seconds since 1970-01-01 00:00:00+00) to
5328     <type>timestamp with time zone</type>.
5329     (<type>Integer</type> Unix epochs are implicitly cast to
5330     <type>double precision</type>.)
5331    </para>
5332
5333     <table id="functions-formatting-table">
5334      <title>Formatting Functions</title>
5335      <tgroup cols="4">
5336       <thead>
5337        <row>
5338         <entry>Function</entry>
5339         <entry>Return Type</entry>
5340         <entry>Description</entry>
5341         <entry>Example</entry>
5342        </row>
5343       </thead>
5344       <tbody>
5345        <row>
5346         <entry>
5347          <indexterm>
5348           <primary>to_char</primary>
5349          </indexterm>
5350          <literal><function>to_char(<type>timestamp</type>, <type>text</type>)</function></literal>
5351         </entry>
5352         <entry><type>text</type></entry>
5353         <entry>convert time stamp to string</entry>
5354         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
5355        </row>
5356        <row>
5357         <entry><literal><function>to_char(<type>interval</type>, <type>text</type>)</function></literal></entry>
5358         <entry><type>text</type></entry>
5359         <entry>convert interval to string</entry>
5360         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
5361        </row>
5362        <row>
5363         <entry><literal><function>to_char(<type>int</type>, <type>text</type>)</function></literal></entry>
5364         <entry><type>text</type></entry>
5365         <entry>convert integer to string</entry>
5366         <entry><literal>to_char(125, '999')</literal></entry>
5367        </row>
5368        <row>
5369         <entry><literal><function>to_char</function>(<type>double precision</type>,
5370         <type>text</type>)</literal></entry>
5371         <entry><type>text</type></entry>
5372         <entry>convert real/double precision to string</entry>
5373         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
5374        </row>
5375        <row>
5376         <entry><literal><function>to_char(<type>numeric</type>, <type>text</type>)</function></literal></entry>
5377         <entry><type>text</type></entry>
5378         <entry>convert numeric to string</entry>
5379         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
5380        </row>
5381        <row>
5382         <entry>
5383          <indexterm>
5384           <primary>to_date</primary>
5385          </indexterm>
5386          <literal><function>to_date(<type>text</type>, <type>text</type>)</function></literal>
5387         </entry>
5388         <entry><type>date</type></entry>
5389         <entry>convert string to date</entry>
5390         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5391        </row>
5392        <row>
5393         <entry>
5394          <indexterm>
5395           <primary>to_number</primary>
5396          </indexterm>
5397          <literal><function>to_number(<type>text</type>, <type>text</type>)</function></literal>
5398         </entry>
5399         <entry><type>numeric</type></entry>
5400         <entry>convert string to numeric</entry>
5401         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
5402        </row>
5403        <row>
5404         <entry>
5405          <indexterm>
5406           <primary>to_timestamp</primary>
5407          </indexterm>
5408          <literal><function>to_timestamp(<type>text</type>, <type>text</type>)</function></literal>
5409         </entry>
5410         <entry><type>timestamp with time zone</type></entry>
5411         <entry>convert string to time stamp</entry>
5412         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5413        </row>
5414        <row>
5415         <entry><literal><function>to_timestamp(<type>double precision</type>)</function></literal></entry>
5416         <entry><type>timestamp with time zone</type></entry>
5417         <entry>convert Unix epoch to time stamp</entry>
5418         <entry><literal>to_timestamp(1284352323)</literal></entry>
5419        </row>
5420       </tbody>
5421      </tgroup>
5422     </table>
5423
5424    <para>
5425     In a <function>to_char</> output template string, there are certain
5426     patterns that are recognized and replaced with appropriately-formatted
5427     data based on the given value.  Any text that is not a template pattern is
5428     simply copied verbatim.  Similarly, in an input template string (for the
5429     other functions), template patterns identify the values to be supplied by
5430     the input data string.
5431    </para>
5432
5433   <para>
5434    <xref linkend="functions-formatting-datetime-table"> shows the
5435    template patterns available for formatting date and time values.
5436   </para>
5437
5438     <table id="functions-formatting-datetime-table">
5439      <title>Template Patterns for Date/Time Formatting</title>
5440      <tgroup cols="2">
5441       <thead>
5442        <row>
5443         <entry>Pattern</entry>
5444         <entry>Description</entry>
5445        </row>
5446       </thead>
5447       <tbody>
5448        <row>
5449         <entry><literal>HH</literal></entry>
5450         <entry>hour of day (01-12)</entry>
5451        </row>
5452        <row>
5453         <entry><literal>HH12</literal></entry>
5454         <entry>hour of day (01-12)</entry>
5455        </row>
5456        <row>
5457         <entry><literal>HH24</literal></entry>
5458         <entry>hour of day (00-23)</entry>
5459        </row>
5460        <row>
5461         <entry><literal>MI</literal></entry>
5462         <entry>minute (00-59)</entry>
5463        </row>
5464        <row>
5465         <entry><literal>SS</literal></entry>
5466         <entry>second (00-59)</entry>
5467        </row>
5468        <row>
5469         <entry><literal>MS</literal></entry>
5470         <entry>millisecond (000-999)</entry>
5471        </row>
5472        <row>
5473         <entry><literal>US</literal></entry>
5474         <entry>microsecond (000000-999999)</entry>
5475        </row>
5476        <row>
5477         <entry><literal>SSSS</literal></entry>
5478         <entry>seconds past midnight (0-86399)</entry>
5479        </row>
5480        <row>
5481         <entry><literal>AM</literal>, <literal>am</literal>,
5482         <literal>PM</literal> or <literal>pm</literal></entry>
5483         <entry>meridiem indicator (without periods)</entry>
5484        </row>
5485        <row>
5486         <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
5487         <literal>P.M.</literal> or <literal>p.m.</literal></entry>
5488         <entry>meridiem indicator (with periods)</entry>
5489        </row>
5490        <row>
5491         <entry><literal>Y,YYY</literal></entry>
5492         <entry>year (4 and more digits) with comma</entry>
5493        </row>
5494        <row>
5495         <entry><literal>YYYY</literal></entry>
5496         <entry>year (4 and more digits)</entry>
5497        </row>
5498        <row>
5499         <entry><literal>YYY</literal></entry>
5500         <entry>last 3 digits of year</entry>
5501        </row>
5502        <row>
5503         <entry><literal>YY</literal></entry>
5504         <entry>last 2 digits of year</entry>
5505        </row>
5506        <row>
5507         <entry><literal>Y</literal></entry>
5508         <entry>last digit of year</entry>
5509        </row>
5510        <row>
5511         <entry><literal>IYYY</literal></entry>
5512         <entry>ISO year (4 and more digits)</entry>
5513        </row>
5514        <row>
5515         <entry><literal>IYY</literal></entry>
5516         <entry>last 3 digits of ISO year</entry>
5517        </row>
5518        <row>
5519         <entry><literal>IY</literal></entry>
5520         <entry>last 2 digits of ISO year</entry>
5521        </row>
5522        <row>
5523         <entry><literal>I</literal></entry>
5524         <entry>last digit of ISO year</entry>
5525        </row>
5526        <row>
5527         <entry><literal>BC</literal>, <literal>bc</literal>,
5528         <literal>AD</literal> or <literal>ad</literal></entry>
5529         <entry>era indicator (without periods)</entry>
5530        </row>
5531        <row>
5532         <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
5533         <literal>A.D.</literal> or <literal>a.d.</literal></entry>
5534         <entry>era indicator (with periods)</entry>
5535        </row>
5536        <row>
5537         <entry><literal>MONTH</literal></entry>
5538         <entry>full upper case month name (blank-padded to 9 chars)</entry>
5539        </row>
5540        <row>
5541         <entry><literal>Month</literal></entry>
5542         <entry>full capitalized month name (blank-padded to 9 chars)</entry>
5543        </row>
5544        <row>
5545         <entry><literal>month</literal></entry>
5546         <entry>full lower case month name (blank-padded to 9 chars)</entry>
5547        </row>
5548        <row>
5549         <entry><literal>MON</literal></entry>
5550         <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
5551        </row>
5552        <row>
5553         <entry><literal>Mon</literal></entry>
5554         <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
5555        </row>
5556        <row>
5557         <entry><literal>mon</literal></entry>
5558         <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
5559        </row>
5560        <row>
5561         <entry><literal>MM</literal></entry>
5562         <entry>month number (01-12)</entry>
5563        </row>
5564        <row>
5565         <entry><literal>DAY</literal></entry>
5566         <entry>full upper case day name (blank-padded to 9 chars)</entry>
5567        </row>
5568        <row>
5569         <entry><literal>Day</literal></entry>
5570         <entry>full capitalized day name (blank-padded to 9 chars)</entry>
5571        </row>
5572        <row>
5573         <entry><literal>day</literal></entry>
5574         <entry>full lower case day name (blank-padded to 9 chars)</entry>
5575        </row>
5576        <row>
5577         <entry><literal>DY</literal></entry>
5578         <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
5579        </row>
5580        <row>
5581         <entry><literal>Dy</literal></entry>
5582         <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
5583        </row>
5584        <row>
5585         <entry><literal>dy</literal></entry>
5586         <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
5587        </row>
5588        <row>
5589         <entry><literal>DDD</literal></entry>
5590         <entry>day of year (001-366)</entry>
5591        </row>
5592        <row>
5593         <entry><literal>IDDD</literal></entry>
5594         <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
5595        </row>
5596        <row>
5597         <entry><literal>DD</literal></entry>
5598         <entry>day of month (01-31)</entry>
5599        </row>
5600        <row>
5601         <entry><literal>D</literal></entry>
5602         <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
5603        </row>
5604        <row>
5605         <entry><literal>ID</literal></entry>
5606         <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
5607        </row>
5608        <row>
5609         <entry><literal>W</literal></entry>
5610         <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
5611        </row>
5612        <row>
5613         <entry><literal>WW</literal></entry>
5614         <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
5615        </row>
5616        <row>
5617         <entry><literal>IW</literal></entry>
5618         <entry>ISO week number of year (01 - 53; the first Thursday of the new year is in week 1.)</entry>
5619        </row>
5620        <row>
5621         <entry><literal>CC</literal></entry>
5622         <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
5623        </row>
5624        <row>
5625         <entry><literal>J</literal></entry>
5626         <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
5627        </row>
5628        <row>
5629         <entry><literal>Q</literal></entry>
5630         <entry>quarter (ignored by <function>to_date</> and <function>to_timestamp</>)</entry>
5631        </row>
5632        <row>
5633         <entry><literal>RM</literal></entry>
5634         <entry>month in upper case Roman numerals (I-XII; I=January)</entry>
5635        </row>
5636        <row>
5637         <entry><literal>rm</literal></entry>
5638         <entry>month in lower case Roman numerals (i-xii; i=January)</entry>
5639        </row>
5640        <row>
5641         <entry><literal>TZ</literal></entry>
5642         <entry>upper case time-zone name</entry>
5643        </row>
5644        <row>
5645         <entry><literal>tz</literal></entry>
5646         <entry>lower case time-zone name</entry>
5647        </row>
5648        <row>
5649         <entry><literal>OF</literal></entry>
5650         <entry>time-zone offset</entry>
5651        </row>
5652       </tbody>
5653      </tgroup>
5654     </table>
5655
5656    <para>
5657     Modifiers can be applied to any template pattern to alter its
5658     behavior.  For example, <literal>FMMonth</literal>
5659     is the <literal>Month</literal> pattern with the
5660     <literal>FM</literal> modifier.
5661     <xref linkend="functions-formatting-datetimemod-table"> shows the
5662     modifier patterns for date/time formatting.
5663    </para>
5664
5665     <table id="functions-formatting-datetimemod-table">
5666      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5667      <tgroup cols="3">
5668       <thead>
5669        <row>
5670         <entry>Modifier</entry>
5671         <entry>Description</entry>
5672         <entry>Example</entry>
5673        </row>
5674       </thead>
5675       <tbody>
5676        <row>
5677         <entry><literal>FM</literal> prefix</entry>
5678         <entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
5679         <entry><literal>FMMonth</literal></entry>
5680        </row>
5681        <row>
5682         <entry><literal>TH</literal> suffix</entry>
5683         <entry>upper case ordinal number suffix</entry>
5684         <entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
5685        </row>
5686        <row>
5687         <entry><literal>th</literal> suffix</entry>
5688         <entry>lower case ordinal number suffix</entry>
5689         <entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
5690        </row>
5691        <row>
5692         <entry><literal>FX</literal> prefix</entry>
5693         <entry>fixed format global option (see usage notes)</entry>
5694         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5695        </row>
5696        <row>
5697         <entry><literal>TM</literal> prefix</entry>
5698         <entry>translation mode (print localized day and month names based on
5699          <xref linkend="guc-lc-time">)</entry>
5700         <entry><literal>TMMonth</literal></entry>
5701        </row>
5702        <row>
5703         <entry><literal>SP</literal> suffix</entry>
5704         <entry>spell mode (not implemented)</entry>
5705         <entry><literal>DDSP</literal></entry>
5706        </row>
5707       </tbody>
5708      </tgroup>
5709     </table>
5710
5711    <para>
5712     Usage notes for date/time formatting:
5713
5714     <itemizedlist>
5715      <listitem>
5716       <para>
5717        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5718        that would otherwise be added to make the output of a pattern be
5719        fixed-width.  In <productname>PostgreSQL</productname>,
5720        <literal>FM</literal> modifies only the next specification, while in
5721        Oracle <literal>FM</literal> affects all subsequent
5722        specifications, and repeated <literal>FM</literal> modifiers
5723        toggle fill mode on and off.
5724       </para>
5725      </listitem>
5726
5727      <listitem>
5728       <para>
5729        <literal>TM</literal> does not include trailing blanks.
5730       </para>
5731      </listitem>
5732
5733      <listitem>
5734       <para>
5735        <function>to_timestamp</function> and <function>to_date</function>
5736        skip multiple blank spaces in the input string unless the
5737        <literal>FX</literal> option is used. For example,
5738        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> works, but
5739        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
5740        because <function>to_timestamp</function> expects one space only.
5741        <literal>FX</literal> must be specified as the first item in
5742        the template.
5743       </para>
5744      </listitem>
5745
5746      <listitem>
5747       <para>
5748        Ordinary text is allowed in <function>to_char</function>
5749        templates and will be output literally.  You can put a substring
5750        in double quotes to force it to be interpreted as literal text
5751        even if it contains pattern key words.  For example, in
5752        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5753        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5754        will not be.  In <function>to_date</>, <function>to_number</>,
5755        and <function>to_timestamp</>, double-quoted strings skip the number of
5756        input characters contained in the string, e.g. <literal>"XX"</>
5757        skips two input characters.
5758       </para>
5759      </listitem>
5760
5761      <listitem>
5762       <para>
5763        If you want to have a double quote in the output you must
5764        precede it with a backslash, for example <literal>'\"YYYY
5765        Month\"'</literal>. <!-- "" font-lock sanity :-) -->
5766       </para>
5767      </listitem>
5768
5769      <listitem>
5770       <para>
5771        If the year format specification is less than four digits, e.g.
5772        <literal>YYY</>, and the supplied year is less than four digits,
5773        the year will be adjusted to be nearest to the year 2020, e.g.
5774        <literal>95</> becomes 1995.
5775       </para>
5776      </listitem>
5777
5778      <listitem>
5779       <para>
5780        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5781        <type>date</type> has a restriction when processing years with more than 4 digits. You must
5782        use some non-digit character or template after <literal>YYYY</literal>,
5783        otherwise the year is always interpreted as 4 digits. For example
5784        (with the year 20000):
5785        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
5786        interpreted as a 4-digit year; instead use a non-digit
5787        separator after the year, like
5788        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5789        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5790       </para>
5791      </listitem>
5792
5793      <listitem>
5794       <para>
5795        In conversions from string to <type>timestamp</type> or
5796        <type>date</type>, the <literal>CC</literal> (century) field is ignored
5797        if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
5798        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5799        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5800        as the year in the specified century.  If the century is
5801        specified but the year is not, the first year of the century
5802        is assumed.
5803       </para>
5804      </listitem>
5805
5806      <listitem>
5807       <para>
5808        An ISO week date (as distinct from a Gregorian date) can be
5809        specified to <function>to_timestamp</function> and
5810        <function>to_date</function> in one of two ways:
5811        <itemizedlist>
5812         <listitem>
5813          <para>
5814           Year, week, and weekday:  for example <literal>to_date('2006-42-4',
5815           'IYYY-IW-ID')</literal> returns the date
5816           <literal>2006-10-19</literal>.  If you omit the weekday it
5817           is assumed to be 1 (Monday).
5818          </para>
5819         </listitem>
5820         <listitem>
5821          <para>
5822           Year and day of year:  for example <literal>to_date('2006-291',
5823           'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5824          </para>
5825         </listitem>
5826        </itemizedlist>
5827       </para>
5828       <para>
5829        Attempting to construct a date using a mixture of ISO week and
5830        Gregorian date fields is nonsensical, and will cause an error.  In the
5831        context of an ISO year, the concept of a <quote>month</> or <quote>day
5832        of month</> has no meaning.  In the context of a Gregorian year, the
5833        ISO week has no meaning.  Users should avoid mixing Gregorian and
5834        ISO date specifications.
5835       </para>
5836      </listitem>
5837
5838      <listitem>
5839       <para>
5840        In a conversion from string to <type>timestamp</type>, millisecond
5841        (<literal>MS</literal>) or microsecond (<literal>US</literal>)
5842        values are used as the
5843        seconds digits after the decimal point. For example
5844        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5845        but 300, because the conversion counts it as 12 + 0.3 seconds.
5846        This means for the format <literal>SS:MS</literal>, the input values
5847        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5848        same number of milliseconds. To get three milliseconds, one must use
5849        <literal>12:003</literal>, which the conversion counts as
5850        12 + 0.003 = 12.003 seconds.
5851       </para>
5852
5853       <para>
5854        Here is a more
5855        complex example:
5856        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5857        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5858        1230 microseconds = 2.021230 seconds.
5859       </para>
5860      </listitem>
5861
5862      <listitem>
5863       <para>
5864         <function>to_char(..., 'ID')</function>'s day of the week numbering
5865         matches the <function>extract(isodow from ...)</function> function, but
5866         <function>to_char(..., 'D')</function>'s does not match
5867         <function>extract(dow from ...)</function>'s day numbering.
5868       </para>
5869      </listitem>
5870
5871      <listitem>
5872       <para>
5873         <function>to_char(interval)</function> formats <literal>HH</> and
5874         <literal>HH12</> as shown on a 12-hour clock, i.e. zero hours
5875         and 36 hours output as <literal>12</>, while <literal>HH24</>
5876         outputs the full hour value, which can exceed 23 for intervals.
5877       </para>
5878      </listitem>
5879
5880     </itemizedlist>
5881    </para>
5882
5883   <para>
5884    <xref linkend="functions-formatting-numeric-table"> shows the
5885    template patterns available for formatting numeric values.
5886   </para>
5887
5888     <table id="functions-formatting-numeric-table">
5889      <title>Template Patterns for Numeric Formatting</title>
5890      <tgroup cols="2">
5891       <thead>
5892        <row>
5893         <entry>Pattern</entry>
5894         <entry>Description</entry>
5895        </row>
5896       </thead>
5897       <tbody>
5898        <row>
5899         <entry><literal>9</literal></entry>
5900         <entry>value with the specified number of digits</entry>
5901        </row>
5902        <row>
5903         <entry><literal>0</literal></entry>
5904         <entry>value with leading zeros</entry>
5905        </row>
5906        <row>
5907         <entry><literal>.</literal> (period)</entry>
5908         <entry>decimal point</entry>
5909        </row>
5910        <row>
5911         <entry><literal>,</literal> (comma)</entry>
5912         <entry>group (thousand) separator</entry>
5913        </row>
5914        <row>
5915         <entry><literal>PR</literal></entry>
5916         <entry>negative value in angle brackets</entry>
5917        </row>
5918        <row>
5919         <entry><literal>S</literal></entry>
5920         <entry>sign anchored to number (uses locale)</entry>
5921        </row>
5922        <row>
5923         <entry><literal>L</literal></entry>
5924         <entry>currency symbol (uses locale)</entry>
5925        </row>
5926        <row>
5927         <entry><literal>D</literal></entry>
5928         <entry>decimal point (uses locale)</entry>
5929        </row>
5930        <row>
5931         <entry><literal>G</literal></entry>
5932         <entry>group separator (uses locale)</entry>
5933        </row>
5934        <row>
5935         <entry><literal>MI</literal></entry>
5936         <entry>minus sign in specified position (if number &lt; 0)</entry>
5937        </row>
5938        <row>
5939         <entry><literal>PL</literal></entry>
5940         <entry>plus sign in specified position (if number &gt; 0)</entry>
5941        </row>
5942        <row>
5943         <entry><literal>SG</literal></entry>
5944         <entry>plus/minus sign in specified position</entry>
5945        </row>
5946        <row>
5947         <entry><literal>RN</literal></entry>
5948         <entry>Roman numeral (input between 1 and 3999)</entry>
5949        </row>
5950        <row>
5951         <entry><literal>TH</literal> or <literal>th</literal></entry>
5952         <entry>ordinal number suffix</entry>
5953        </row>
5954        <row>
5955         <entry><literal>V</literal></entry>
5956         <entry>shift specified number of digits (see notes)</entry>
5957        </row>
5958        <row>
5959         <entry><literal>EEEE</literal></entry>
5960         <entry>exponent for scientific notation</entry>
5961        </row>
5962       </tbody>
5963      </tgroup>
5964     </table>
5965
5966    <para>
5967     Usage notes for numeric formatting:
5968
5969     <itemizedlist>
5970      <listitem>
5971       <para>
5972        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5973        <literal>MI</literal> is not anchored to
5974        the number; for example,
5975        <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
5976        but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
5977        The Oracle implementation does not allow the use of
5978        <literal>MI</literal> before <literal>9</literal>, but rather
5979        requires that <literal>9</literal> precede
5980        <literal>MI</literal>.
5981       </para>
5982      </listitem>
5983
5984      <listitem>
5985       <para>
5986        <literal>9</literal> results in a value with the same number of
5987        digits as there are <literal>9</literal>s. If a digit is
5988        not available it outputs a space.
5989       </para>
5990      </listitem>
5991
5992      <listitem>
5993       <para>
5994        <literal>TH</literal> does not convert values less than zero
5995        and does not convert fractional numbers.
5996       </para>
5997      </listitem>
5998
5999      <listitem>
6000       <para>
6001        <literal>PL</literal>, <literal>SG</literal>, and
6002        <literal>TH</literal> are <productname>PostgreSQL</productname>
6003        extensions.
6004       </para>
6005      </listitem>
6006
6007      <listitem>
6008       <para>
6009        <literal>V</literal> effectively
6010        multiplies the input values by
6011        <literal>10^<replaceable>n</replaceable></literal>, where
6012        <replaceable>n</replaceable> is the number of digits following
6013        <literal>V</literal>.
6014        <function>to_char</function> does not support the use of
6015        <literal>V</literal> combined with a decimal point
6016        (e.g., <literal>99.9V99</literal> is not allowed).
6017       </para>
6018      </listitem>
6019
6020      <listitem>
6021       <para>
6022        <literal>EEEE</literal> (scientific notation) cannot be used in
6023        combination with any of the other formatting patterns or
6024        modifiers other than digit and decimal point patterns, and must be at the end of the format string
6025        (e.g., <literal>9.99EEEE</literal> is a valid pattern).
6026       </para>
6027      </listitem>
6028     </itemizedlist>
6029    </para>
6030
6031    <para>
6032     Certain modifiers can be applied to any template pattern to alter its
6033     behavior.  For example, <literal>FM9999</literal>
6034     is the <literal>9999</literal> pattern with the
6035     <literal>FM</literal> modifier.
6036     <xref linkend="functions-formatting-numericmod-table"> shows the
6037     modifier patterns for numeric formatting.
6038    </para>
6039
6040     <table id="functions-formatting-numericmod-table">
6041      <title>Template Pattern Modifiers for Numeric Formatting</title>
6042      <tgroup cols="3">
6043       <thead>
6044        <row>
6045         <entry>Modifier</entry>
6046         <entry>Description</entry>
6047         <entry>Example</entry>
6048        </row>
6049       </thead>
6050       <tbody>
6051        <row>
6052         <entry><literal>FM</literal> prefix</entry>
6053         <entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
6054         <entry><literal>FM9999</literal></entry>
6055        </row>
6056        <row>
6057         <entry><literal>TH</literal> suffix</entry>
6058         <entry>upper case ordinal number suffix</entry>
6059         <entry><literal>999TH</literal></entry>
6060        </row>
6061        <row>
6062         <entry><literal>th</literal> suffix</entry>
6063         <entry>lower case ordinal number suffix</entry>
6064         <entry><literal>999th</literal></entry>
6065        </row>
6066       </tbody>
6067      </tgroup>
6068     </table>
6069
6070   <para>
6071    <xref linkend="functions-formatting-examples-table"> shows some
6072    examples of the use of the <function>to_char</function> function.
6073   </para>
6074
6075     <table id="functions-formatting-examples-table">
6076      <title><function>to_char</function> Examples</title>
6077      <tgroup cols="2">
6078       <thead>
6079        <row>
6080         <entry>Expression</entry>
6081         <entry>Result</entry>
6082        </row>
6083       </thead>
6084       <tbody>
6085        <row>
6086         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
6087         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
6088        </row>
6089        <row>
6090         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
6091         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
6092        </row>
6093        <row>
6094         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
6095         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
6096        </row>
6097        <row>
6098         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
6099         <entry><literal>'-.1'</literal></entry>
6100        </row>
6101        <row>
6102         <entry><literal>to_char(0.1, '0.9')</literal></entry>
6103         <entry><literal>'&nbsp;0.1'</literal></entry>
6104        </row>
6105        <row>
6106         <entry><literal>to_char(12, '9990999.9')</literal></entry>
6107         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
6108        </row>
6109        <row>
6110         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
6111         <entry><literal>'0012.'</literal></entry>
6112        </row>
6113        <row>
6114         <entry><literal>to_char(485, '999')</literal></entry>
6115         <entry><literal>'&nbsp;485'</literal></entry>
6116        </row>
6117        <row>
6118         <entry><literal>to_char(-485, '999')</literal></entry>
6119         <entry><literal>'-485'</literal></entry>
6120        </row>
6121        <row>
6122         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
6123         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
6124        </row>
6125        <row>
6126         <entry><literal>to_char(1485, '9,999')</literal></entry>
6127         <entry><literal>'&nbsp;1,485'</literal></entry>
6128        </row>
6129        <row>
6130         <entry><literal>to_char(1485, '9G999')</literal></entry>
6131         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
6132        </row>
6133        <row>
6134         <entry><literal>to_char(148.5, '999.999')</literal></entry>
6135         <entry><literal>'&nbsp;148.500'</literal></entry>
6136        </row>
6137        <row>
6138         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
6139         <entry><literal>'148.5'</literal></entry>
6140        </row>
6141        <row>
6142         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
6143         <entry><literal>'148.500'</literal></entry>
6144        </row>
6145        <row>
6146         <entry><literal>to_char(148.5, '999D999')</literal></entry>
6147         <entry><literal>'&nbsp;148,500'</literal></entry>
6148        </row>
6149        <row>
6150         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
6151         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
6152        </row>
6153        <row>
6154         <entry><literal>to_char(-485, '999S')</literal></entry>
6155         <entry><literal>'485-'</literal></entry>
6156        </row>
6157        <row>
6158         <entry><literal>to_char(-485, '999MI')</literal></entry>
6159         <entry><literal>'485-'</literal></entry>
6160        </row>
6161        <row>
6162         <entry><literal>to_char(485, '999MI')</literal></entry>
6163         <entry><literal>'485&nbsp;'</literal></entry>
6164        </row>
6165        <row>
6166         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
6167         <entry><literal>'485'</literal></entry>
6168        </row>
6169        <row>
6170         <entry><literal>to_char(485, 'PL999')</literal></entry>
6171         <entry><literal>'+485'</literal></entry>
6172        </row>
6173        <row>
6174         <entry><literal>to_char(485, 'SG999')</literal></entry>
6175         <entry><literal>'+485'</literal></entry>
6176        </row>
6177        <row>
6178         <entry><literal>to_char(-485, 'SG999')</literal></entry>
6179         <entry><literal>'-485'</literal></entry>
6180        </row>
6181        <row>
6182         <entry><literal>to_char(-485, '9SG99')</literal></entry>
6183         <entry><literal>'4-85'</literal></entry>
6184        </row>
6185        <row>
6186         <entry><literal>to_char(-485, '999PR')</literal></entry>
6187         <entry><literal>'&lt;485&gt;'</literal></entry>
6188        </row>
6189        <row>
6190         <entry><literal>to_char(485, 'L999')</literal></entry>
6191         <entry><literal>'DM&nbsp;485</literal></entry>
6192        </row>
6193        <row>
6194         <entry><literal>to_char(485, 'RN')</literal></entry>
6195         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
6196        </row>
6197        <row>
6198         <entry><literal>to_char(485, 'FMRN')</literal></entry>
6199         <entry><literal>'CDLXXXV'</literal></entry>
6200        </row>
6201        <row>
6202         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
6203         <entry><literal>'V'</literal></entry>
6204        </row>
6205        <row>
6206         <entry><literal>to_char(482, '999th')</literal></entry>
6207         <entry><literal>'&nbsp;482nd'</literal></entry>
6208        </row>
6209        <row>
6210         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
6211         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
6212        </row>
6213        <row>
6214         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
6215         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
6216        </row>
6217        <row>
6218         <entry><literal>to_char(12, '99V999')</literal></entry>
6219         <entry><literal>'&nbsp;12000'</literal></entry>
6220        </row>
6221        <row>
6222         <entry><literal>to_char(12.4, '99V999')</literal></entry>
6223         <entry><literal>'&nbsp;12400'</literal></entry>
6224        </row>
6225        <row>
6226         <entry><literal>to_char(12.45, '99V9')</literal></entry>
6227         <entry><literal>'&nbsp;125'</literal></entry>
6228        </row>
6229        <row>
6230         <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
6231         <entry><literal>' 4.86e-04'</literal></entry>
6232        </row>
6233       </tbody>
6234      </tgroup>
6235     </table>
6236
6237   </sect1>
6238
6239
6240   <sect1 id="functions-datetime">
6241    <title>Date/Time Functions and Operators</title>
6242
6243   <para>
6244    <xref linkend="functions-datetime-table"> shows the available
6245    functions for date/time value processing, with details appearing in
6246    the following subsections.  <xref
6247    linkend="operators-datetime-table"> illustrates the behaviors of
6248    the basic arithmetic operators (<literal>+</literal>,
6249    <literal>*</literal>, etc.).  For formatting functions, refer to
6250    <xref linkend="functions-formatting">.  You should be familiar with
6251    the background information on date/time data types from <xref
6252    linkend="datatype-datetime">.
6253   </para>
6254
6255   <para>
6256    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
6257    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
6258    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
6259    For brevity, these variants are not shown separately.  Also, the
6260    <literal>+</> and <literal>*</> operators come in commutative pairs (for
6261    example both date + integer and integer + date); we show only one of each
6262    such pair.
6263   </para>
6264
6265     <table id="operators-datetime-table">
6266      <title>Date/Time Operators</title>
6267
6268      <tgroup cols="3">
6269       <thead>
6270        <row>
6271         <entry>Operator</entry>
6272         <entry>Example</entry>
6273         <entry>Result</entry>
6274        </row>
6275       </thead>
6276
6277       <tbody>
6278        <row>
6279         <entry> <literal>+</literal> </entry>
6280         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
6281         <entry><literal>date '2001-10-05'</literal></entry>
6282        </row>
6283
6284        <row>
6285         <entry> <literal>+</literal> </entry>
6286         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
6287         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
6288        </row>
6289
6290        <row>
6291         <entry> <literal>+</literal> </entry>
6292         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
6293         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
6294        </row>
6295
6296        <row>
6297         <entry> <literal>+</literal> </entry>
6298         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
6299         <entry><literal>interval '1 day 01:00:00'</literal></entry>
6300        </row>
6301
6302        <row>
6303         <entry> <literal>+</literal> </entry>
6304         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
6305         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
6306        </row>
6307
6308        <row>
6309         <entry> <literal>+</literal> </entry>
6310         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
6311         <entry><literal>time '04:00:00'</literal></entry>
6312        </row>
6313
6314        <row>
6315         <entry> <literal>-</literal> </entry>
6316         <entry><literal>- interval '23 hours'</literal></entry>
6317         <entry><literal>interval '-23:00:00'</literal></entry>
6318        </row>
6319
6320        <row>
6321         <entry> <literal>-</literal> </entry>
6322         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
6323         <entry><literal>integer '3'</literal> (days)</entry>
6324        </row>
6325
6326        <row>
6327         <entry> <literal>-</literal> </entry>
6328         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
6329         <entry><literal>date '2001-09-24'</literal></entry>
6330        </row>
6331
6332        <row>
6333         <entry> <literal>-</literal> </entry>
6334         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
6335         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
6336        </row>
6337
6338        <row>
6339         <entry> <literal>-</literal> </entry>
6340         <entry><literal>time '05:00' - time '03:00'</literal></entry>
6341         <entry><literal>interval '02:00:00'</literal></entry>
6342        </row>
6343
6344        <row>
6345         <entry> <literal>-</literal> </entry>
6346         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
6347         <entry><literal>time '03:00:00'</literal></entry>
6348        </row>
6349
6350        <row>
6351         <entry> <literal>-</literal> </entry>
6352         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
6353         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
6354        </row>
6355
6356        <row>
6357         <entry> <literal>-</literal> </entry>
6358         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
6359         <entry><literal>interval '1 day -01:00:00'</literal></entry>
6360        </row>
6361
6362        <row>
6363         <entry> <literal>-</literal> </entry>
6364         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
6365         <entry><literal>interval '1 day 15:00:00'</literal></entry>
6366        </row>
6367
6368        <row>
6369         <entry> <literal>*</literal> </entry>
6370         <entry><literal>900 * interval '1 second'</literal></entry>
6371         <entry><literal>interval '00:15:00'</literal></entry>
6372        </row>
6373
6374        <row>
6375         <entry> <literal>*</literal> </entry>
6376         <entry><literal>21 * interval '1 day'</literal></entry>
6377         <entry><literal>interval '21 days'</literal></entry>
6378        </row>
6379
6380        <row>
6381         <entry> <literal>*</literal> </entry>
6382         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
6383         <entry><literal>interval '03:30:00'</literal></entry>
6384        </row>
6385
6386        <row>
6387         <entry> <literal>/</literal> </entry>
6388         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
6389         <entry><literal>interval '00:40:00'</literal></entry>
6390        </row>
6391       </tbody>
6392      </tgroup>
6393     </table>
6394
6395     <table id="functions-datetime-table">
6396      <title>Date/Time Functions</title>
6397      <tgroup cols="5">
6398       <thead>
6399        <row>
6400         <entry>Function</entry>
6401         <entry>Return Type</entry>
6402         <entry>Description</entry>
6403         <entry>Example</entry>
6404         <entry>Result</entry>
6405        </row>
6406       </thead>
6407
6408       <tbody>
6409        <row>
6410         <entry>
6411          <indexterm>
6412           <primary>age</primary>
6413          </indexterm>
6414          <literal><function>age(<type>timestamp</type>, <type>timestamp</type>)</function></literal>
6415         </entry>
6416         <entry><type>interval</type></entry>
6417         <entry>Subtract arguments, producing a <quote>symbolic</> result that
6418         uses years and months</entry>
6419         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
6420         <entry><literal>43 years 9 mons 27 days</literal></entry>
6421        </row>
6422
6423        <row>
6424         <entry><literal><function>age(<type>timestamp</type>)</function></literal></entry>
6425         <entry><type>interval</type></entry>
6426         <entry>Subtract from <function>current_date</function> (at midnight)</entry>
6427         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
6428         <entry><literal>43 years 8 mons 3 days</literal></entry>
6429        </row>
6430
6431        <row>
6432         <entry>
6433          <indexterm>
6434           <primary>clock_timestamp</primary>
6435          </indexterm>
6436          <literal><function>clock_timestamp()</function></literal>
6437         </entry>
6438         <entry><type>timestamp with time zone</type></entry>
6439         <entry>Current date and time (changes during statement execution);
6440          see <xref linkend="functions-datetime-current">
6441         </entry>
6442         <entry></entry>
6443         <entry></entry>
6444        </row>
6445
6446        <row>
6447         <entry>
6448          <indexterm>
6449           <primary>current_date</primary>
6450          </indexterm>
6451          <literal><function>current_date</function></literal>
6452         </entry>
6453         <entry><type>date</type></entry>
6454         <entry>Current date;
6455          see <xref linkend="functions-datetime-current">
6456         </entry>
6457         <entry></entry>
6458         <entry></entry>
6459        </row>
6460
6461        <row>
6462         <entry>
6463          <indexterm>
6464           <primary>current_time</primary>
6465          </indexterm>
6466          <literal><function>current_time</function></literal>
6467         </entry>
6468         <entry><type>time with time zone</type></entry>
6469         <entry>Current time of day;
6470          see <xref linkend="functions-datetime-current">
6471         </entry>
6472         <entry></entry>
6473         <entry></entry>
6474        </row>
6475
6476        <row>
6477         <entry>
6478          <indexterm>
6479           <primary>current_timestamp</primary>
6480          </indexterm>
6481          <literal><function>current_timestamp</function></literal>
6482         </entry>
6483         <entry><type>timestamp with time zone</type></entry>
6484         <entry>Current date and time (start of current transaction);
6485          see <xref linkend="functions-datetime-current">
6486         </entry>
6487         <entry></entry>
6488         <entry></entry>
6489        </row>
6490
6491        <row>
6492         <entry>
6493          <indexterm>
6494           <primary>date_part</primary>
6495          </indexterm>
6496          <literal><function>date_part(<type>text</type>, <type>timestamp</type>)</function></literal>
6497         </entry>
6498         <entry><type>double precision</type></entry>
6499         <entry>Get subfield (equivalent to <function>extract</function>);
6500          see <xref linkend="functions-datetime-extract">
6501         </entry>
6502         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6503         <entry><literal>20</literal></entry>
6504        </row>
6505
6506        <row>
6507         <entry><literal><function>date_part(<type>text</type>, <type>interval</type>)</function></literal></entry>
6508         <entry><type>double precision</type></entry>
6509         <entry>Get subfield (equivalent to
6510          <function>extract</function>); see <xref linkend="functions-datetime-extract">
6511         </entry>
6512         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
6513         <entry><literal>3</literal></entry>
6514        </row>
6515
6516        <row>
6517         <entry>
6518          <indexterm>
6519           <primary>date_trunc</primary>
6520          </indexterm>
6521          <literal><function>date_trunc(<type>text</type>, <type>timestamp</type>)</function></literal>
6522         </entry>
6523         <entry><type>timestamp</type></entry>
6524         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
6525         </entry>
6526         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6527         <entry><literal>2001-02-16 20:00:00</literal></entry>
6528        </row>
6529
6530        <row>
6531         <entry>
6532          <indexterm>
6533           <primary>extract</primary>
6534          </indexterm>
6535          <literal><function>extract</function>(<parameter>field</parameter> from
6536          <type>timestamp</type>)</literal>
6537         </entry>
6538         <entry><type>double precision</type></entry>
6539         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6540         </entry>
6541         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
6542         <entry><literal>20</literal></entry>
6543        </row>
6544
6545        <row>
6546         <entry><literal><function>extract</function>(<parameter>field</parameter> from
6547          <type>interval</type>)</literal></entry>
6548         <entry><type>double precision</type></entry>
6549         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6550         </entry>
6551         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
6552         <entry><literal>3</literal></entry>
6553        </row>
6554
6555        <row>
6556         <entry>
6557          <indexterm>
6558           <primary>isfinite</primary>
6559          </indexterm>
6560          <literal><function>isfinite(<type>date</type>)</function></literal>
6561         </entry>
6562         <entry><type>boolean</type></entry>
6563         <entry>Test for finite date (not +/-infinity)</entry>
6564         <entry><literal>isfinite(date '2001-02-16')</literal></entry>
6565         <entry><literal>true</literal></entry>
6566        </row>
6567
6568        <row>
6569         <entry><literal><function>isfinite(<type>timestamp</type>)</function></literal></entry>
6570         <entry><type>boolean</type></entry>
6571         <entry>Test for finite time stamp (not +/-infinity)</entry>
6572         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
6573         <entry><literal>true</literal></entry>
6574        </row>
6575
6576        <row>
6577         <entry><literal><function>isfinite(<type>interval</type>)</function></literal></entry>
6578         <entry><type>boolean</type></entry>
6579         <entry>Test for finite interval</entry>
6580         <entry><literal>isfinite(interval '4 hours')</literal></entry>
6581         <entry><literal>true</literal></entry>
6582        </row>
6583
6584        <row>
6585         <entry>
6586          <indexterm>
6587           <primary>justify_days</primary>
6588          </indexterm>
6589          <literal><function>justify_days(<type>interval</type>)</function></literal>
6590         </entry>
6591         <entry><type>interval</type></entry>
6592         <entry>Adjust interval so 30-day time periods are represented as months</entry>
6593         <entry><literal>justify_days(interval '35 days')</literal></entry>
6594         <entry><literal>1 mon 5 days</literal></entry>
6595        </row>
6596
6597        <row>
6598         <entry>
6599          <indexterm>
6600           <primary>justify_hours</primary>
6601          </indexterm>
6602          <literal><function>justify_hours(<type>interval</type>)</function></literal>
6603         </entry>
6604         <entry><type>interval</type></entry>
6605         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
6606         <entry><literal>justify_hours(interval '27 hours')</literal></entry>
6607         <entry><literal>1 day 03:00:00</literal></entry>
6608        </row>
6609
6610        <row>
6611         <entry>
6612          <indexterm>
6613           <primary>justify_interval</primary>
6614          </indexterm>
6615          <literal><function>justify_interval(<type>interval</type>)</function></literal>
6616         </entry>
6617         <entry><type>interval</type></entry>
6618         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
6619         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
6620         <entry><literal>29 days 23:00:00</literal></entry>
6621        </row>
6622
6623        <row>
6624         <entry>
6625          <indexterm>
6626           <primary>localtime</primary>
6627          </indexterm>
6628          <literal><function>localtime</function></literal>
6629         </entry>
6630         <entry><type>time</type></entry>
6631         <entry>Current time of day;
6632          see <xref linkend="functions-datetime-current">
6633         </entry>
6634         <entry></entry>
6635         <entry></entry>
6636        </row>
6637
6638        <row>
6639         <entry>
6640          <indexterm>
6641           <primary>localtimestamp</primary>
6642          </indexterm>
6643          <literal><function>localtimestamp</function></literal>
6644         </entry>
6645         <entry><type>timestamp</type></entry>
6646         <entry>Current date and time (start of current transaction);
6647          see <xref linkend="functions-datetime-current">
6648         </entry>
6649         <entry></entry>
6650         <entry></entry>
6651        </row>
6652
6653        <row>
6654         <entry>
6655          <indexterm>
6656           <primary>now</primary>
6657          </indexterm>
6658          <literal><function>now()</function></literal>
6659         </entry>
6660         <entry><type>timestamp with time zone</type></entry>
6661         <entry>Current date and time (start of current transaction);
6662          see <xref linkend="functions-datetime-current">
6663         </entry>
6664         <entry></entry>
6665         <entry></entry>
6666        </row>
6667
6668        <row>
6669         <entry>
6670          <indexterm>
6671           <primary>statement_timestamp</primary>
6672          </indexterm>
6673          <literal><function>statement_timestamp()</function></literal>
6674         </entry>
6675         <entry><type>timestamp with time zone</type></entry>
6676         <entry>Current date and time (start of current statement);
6677          see <xref linkend="functions-datetime-current">
6678         </entry>
6679         <entry></entry>
6680         <entry></entry>
6681        </row>
6682
6683        <row>
6684         <entry>
6685          <indexterm>
6686           <primary>timeofday</primary>
6687          </indexterm>
6688          <literal><function>timeofday()</function></literal>
6689         </entry>
6690         <entry><type>text</type></entry>
6691         <entry>Current date and time
6692          (like <function>clock_timestamp</>, but as a <type>text</> string);
6693          see <xref linkend="functions-datetime-current">
6694         </entry>
6695         <entry></entry>
6696         <entry></entry>
6697        </row>
6698
6699        <row>
6700         <entry>
6701          <indexterm>
6702           <primary>transaction_timestamp</primary>
6703          </indexterm>
6704          <literal><function>transaction_timestamp()</function></literal>
6705         </entry>
6706         <entry><type>timestamp with time zone</type></entry>
6707         <entry>Current date and time (start of current transaction);
6708          see <xref linkend="functions-datetime-current">
6709         </entry>
6710         <entry></entry>
6711         <entry></entry>
6712        </row>
6713       </tbody>
6714      </tgroup>
6715     </table>
6716
6717    <para>
6718     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6719     supported:
6720 <synopsis>
6721 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6722 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6723 </synopsis>
6724     This expression yields true when two time periods (defined by their
6725     endpoints) overlap, false when they do not overlap.  The endpoints
6726     can be specified as pairs of dates, times, or time stamps; or as
6727     a date, time, or time stamp followed by an interval.  When a pair
6728     of values is provided, either the start or the end can be written
6729     first; <literal>OVERLAPS</> automatically takes the earlier value
6730     of the pair as the start.  Each time period is considered to
6731     represent the half-open interval <replaceable>start</> <literal>&lt;=</>
6732     <replaceable>time</> <literal>&lt;</> <replaceable>end</>, unless
6733     <replaceable>start</> and <replaceable>end</> are equal in which case it
6734     represents that single time instant.  This means for instance that two
6735     time periods with only an endpoint in common do not overlap.
6736    </para>
6737
6738 <screen>
6739 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6740        (DATE '2001-10-30', DATE '2002-10-30');
6741 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6742 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6743        (DATE '2001-10-30', DATE '2002-10-30');
6744 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6745 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
6746        (DATE '2001-10-30', DATE '2001-10-31');
6747 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6748 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
6749        (DATE '2001-10-30', DATE '2001-10-31');
6750 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6751 </screen>
6752
6753   <para>
6754    When adding an <type>interval</type> value to (or subtracting an
6755    <type>interval</type> value from) a <type>timestamp with time zone</type>
6756    value, the days component advances (or decrements) the date of the
6757    <type>timestamp with time zone</type> by the indicated number of days.
6758    Across daylight saving time changes (with the session time zone set to a
6759    time zone that recognizes DST), this means <literal>interval '1 day'</literal>
6760    does not necessarily equal <literal>interval '24 hours'</literal>.
6761    For example, with the session time zone set to <literal>CST7CDT</literal>,
6762    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
6763    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>,
6764    while adding <literal>interval '24 hours'</literal> to the same initial
6765    <type>timestamp with time zone</type> produces
6766    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6767    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone
6768    <literal>CST7CDT</literal>.
6769   </para>
6770
6771   <para>
6772    Note there can be ambiguity in the <literal>months</> returned by
6773    <function>age</> because different months have a different number of
6774    days.  <productname>PostgreSQL</>'s approach uses the month from the
6775    earlier of the two dates when calculating partial months.  For example,
6776    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6777    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6778    days</> because May has 31 days, while April has only 30.
6779   </para>
6780
6781   <sect2 id="functions-datetime-extract">
6782    <title><function>EXTRACT</function>, <function>date_part</function></title>
6783
6784    <indexterm>
6785     <primary>date_part</primary>
6786    </indexterm>
6787    <indexterm>
6788     <primary>extract</primary>
6789    </indexterm>
6790
6791 <synopsis>
6792 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6793 </synopsis>
6794
6795    <para>
6796     The <function>extract</function> function retrieves subfields
6797     such as year or hour from date/time values.
6798     <replaceable>source</replaceable> must be a value expression of
6799     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6800     (Expressions of type <type>date</type> are
6801     cast to <type>timestamp</type> and can therefore be used as
6802     well.)  <replaceable>field</replaceable> is an identifier or
6803     string that selects what field to extract from the source value.
6804     The <function>extract</function> function returns values of type
6805     <type>double precision</type>.
6806     The following are valid field names:
6807
6808     <!-- alphabetical -->
6809     <variablelist>
6810      <varlistentry>
6811       <term><literal>century</literal></term>
6812       <listitem>
6813        <para>
6814         The century
6815        </para>
6816
6817 <screen>
6818 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6819 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6820 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6821 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6822 </screen>
6823
6824        <para>
6825         The first century starts at 0001-01-01 00:00:00 AD, although
6826         they did not know it at the time. This definition applies to all
6827         Gregorian calendar countries. There is no century number 0,
6828         you go from -1 century to 1 century.
6829
6830         If you disagree with this, please write your complaint to:
6831         Pope, Cathedral Saint-Peter of Roma, Vatican.
6832        </para>
6833
6834        <para>
6835         <productname>PostgreSQL</productname> releases before 8.0 did not
6836         follow the conventional numbering of centuries, but just returned
6837         the year field divided by 100.
6838        </para>
6839       </listitem>
6840      </varlistentry>
6841
6842      <varlistentry>
6843       <term><literal>day</literal></term>
6844       <listitem>
6845        <para>
6846         For <type>timestamp</type> values, the day (of the month) field
6847         (1 - 31) ; for <type>interval</type> values, the number of days
6848        </para>
6849
6850 <screen>
6851 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6852 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6853
6854 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
6855 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6856 </screen>
6857
6858
6859
6860       </listitem>
6861      </varlistentry>
6862
6863      <varlistentry>
6864       <term><literal>decade</literal></term>
6865       <listitem>
6866        <para>
6867         The year field divided by 10
6868        </para>
6869
6870 <screen>
6871 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6872 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6873 </screen>
6874       </listitem>
6875      </varlistentry>
6876
6877      <varlistentry>
6878       <term><literal>dow</literal></term>
6879       <listitem>
6880        <para>
6881         The day of the week as Sunday(<literal>0</>) to
6882         Saturday(<literal>6</>)
6883        </para>
6884
6885 <screen>
6886 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6887 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6888 </screen>
6889        <para>
6890         Note that <function>extract</function>'s day of the week numbering
6891         differs from that of the <function>to_char(...,
6892         'D')</function> function.
6893        </para>
6894
6895       </listitem>
6896      </varlistentry>
6897
6898      <varlistentry>
6899       <term><literal>doy</literal></term>
6900       <listitem>
6901        <para>
6902         The day of the year (1 - 365/366)
6903        </para>
6904
6905 <screen>
6906 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6907 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6908 </screen>
6909       </listitem>
6910      </varlistentry>
6911
6912      <varlistentry>
6913       <term><literal>epoch</literal></term>
6914       <listitem>
6915        <para>
6916         For <type>timestamp with time zone</type> values, the
6917         number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
6918         for <type>date</type> and <type>timestamp</type> values, the
6919         number of seconds since 1970-01-01 00:00:00 local time;
6920         for <type>interval</type> values, the total number
6921         of seconds in the interval
6922        </para>
6923
6924 <screen>
6925 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
6926 <lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput>
6927
6928 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6929 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6930 </screen>
6931
6932        <para>
6933         Here is how you can convert an epoch value back to a time
6934         stamp:
6935        </para>
6936 <screen>
6937 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second';
6938 </screen>
6939        <para>
6940         (The <function>to_timestamp</> function encapsulates the above
6941         conversion.)
6942        </para>
6943       </listitem>
6944      </varlistentry>
6945
6946      <varlistentry>
6947       <term><literal>hour</literal></term>
6948       <listitem>
6949        <para>
6950         The hour field (0 - 23)
6951        </para>
6952
6953 <screen>
6954 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6955 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6956 </screen>
6957       </listitem>
6958      </varlistentry>
6959
6960      <varlistentry>
6961       <term><literal>isodow</literal></term>
6962       <listitem>
6963        <para>
6964         The day of the week as Monday(<literal>1</>) to
6965         Sunday(<literal>7</>)
6966        </para>
6967
6968 <screen>
6969 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6970 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6971 </screen>
6972        <para>
6973         This is identical to <literal>dow</> except for Sunday.  This
6974         matches the <acronym>ISO</> 8601 day of the week numbering.
6975        </para>
6976
6977       </listitem>
6978      </varlistentry>
6979
6980      <varlistentry>
6981       <term><literal>isoyear</literal></term>
6982       <listitem>
6983        <para>
6984         The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals)
6985        </para>
6986
6987 <screen>
6988 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6989 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6990 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6991 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6992 </screen>
6993
6994        <para>
6995         Each <acronym>ISO</acronym> year begins with the Monday of the week containing the 4th of January, so in early January or late December the <acronym>ISO</acronym> year may be different from the Gregorian year.  See the <literal>week</literal> field for more information.
6996        </para>
6997        <para>
6998         This field is not available in PostgreSQL releases prior to 8.3.
6999        </para>
7000       </listitem>
7001      </varlistentry>
7002
7003      <varlistentry>
7004       <term><literal>microseconds</literal></term>
7005       <listitem>
7006        <para>
7007         The seconds field, including fractional parts, multiplied by 1
7008         000 000;  note that this includes full seconds
7009        </para>
7010
7011 <screen>
7012 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
7013 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
7014 </screen>
7015       </listitem>
7016      </varlistentry>
7017
7018      <varlistentry>
7019       <term><literal>millennium</literal></term>
7020       <listitem>
7021        <para>
7022         The millennium
7023        </para>
7024
7025 <screen>
7026 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
7027 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
7028 </screen>
7029
7030        <para>
7031         Years in the 1900s are in the second millennium.
7032         The third millennium started January 1, 2001.
7033        </para>
7034
7035        <para>
7036         <productname>PostgreSQL</productname> releases before 8.0 did not
7037         follow the conventional numbering of millennia, but just returned
7038         the year field divided by 1000.
7039        </para>
7040       </listitem>
7041      </varlistentry>
7042
7043      <varlistentry>
7044       <term><literal>milliseconds</literal></term>
7045       <listitem>
7046        <para>
7047         The seconds field, including fractional parts, multiplied by
7048         1000.  Note that this includes full seconds.
7049        </para>
7050
7051 <screen>
7052 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
7053 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
7054 </screen>
7055       </listitem>
7056      </varlistentry>
7057
7058      <varlistentry>
7059       <term><literal>minute</literal></term>
7060       <listitem>
7061        <para>
7062         The minutes field (0 - 59)
7063        </para>
7064
7065 <screen>
7066 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
7067 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
7068 </screen>
7069       </listitem>
7070      </varlistentry>
7071
7072      <varlistentry>
7073       <term><literal>month</literal></term>
7074       <listitem>
7075        <para>
7076         For <type>timestamp</type> values, the number of the month
7077         within the year (1 - 12) ; for <type>interval</type> values,
7078         the number of months, modulo 12 (0 - 11)
7079        </para>
7080
7081 <screen>
7082 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
7083 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
7084
7085 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
7086 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
7087
7088 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
7089 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7090 </screen>
7091       </listitem>
7092      </varlistentry>
7093
7094      <varlistentry>
7095       <term><literal>quarter</literal></term>
7096       <listitem>
7097        <para>
7098         The quarter of the year (1 - 4) that the date is in
7099        </para>
7100
7101 <screen>
7102 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
7103 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7104 </screen>
7105       </listitem>
7106      </varlistentry>
7107
7108      <varlistentry>
7109       <term><literal>second</literal></term>
7110       <listitem>
7111        <para>
7112         The seconds field, including fractional parts (0 -
7113         59<footnote><simpara>60 if leap seconds are
7114         implemented by the operating system</simpara></footnote>)
7115        </para>
7116
7117 <screen>
7118 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
7119 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
7120
7121 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
7122 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
7123 </screen>
7124       </listitem>
7125      </varlistentry>
7126      <varlistentry>
7127       <term><literal>timezone</literal></term>
7128       <listitem>
7129        <para>
7130         The time zone offset from UTC, measured in seconds.  Positive values
7131         correspond to time zones east of UTC, negative values to
7132         zones west of UTC.  (Technically,
7133         <productname>PostgreSQL</productname> uses <acronym>UT1</> because
7134         leap seconds are not handled.)
7135        </para>
7136       </listitem>
7137      </varlistentry>
7138
7139      <varlistentry>
7140       <term><literal>timezone_hour</literal></term>
7141       <listitem>
7142        <para>
7143         The hour component of the time zone offset
7144        </para>
7145       </listitem>
7146      </varlistentry>
7147
7148      <varlistentry>
7149       <term><literal>timezone_minute</literal></term>
7150       <listitem>
7151        <para>
7152         The minute component of the time zone offset
7153        </para>
7154       </listitem>
7155      </varlistentry>
7156
7157      <varlistentry>
7158       <term><literal>week</literal></term>
7159       <listitem>
7160        <para>
7161         The number of the week of the year that the day is in.  By definition
7162         (<acronym>ISO</acronym> 8601), weeks start on Mondays and the first
7163         week of a year contains January 4 of that year.  In other words, the
7164         first Thursday of a year is in week 1 of that year.
7165        </para>
7166        <para>
7167         In the ISO definition, it is possible for early-January dates to be
7168         part of the 52nd or 53rd week of the previous year, and for
7169         late-December dates to be part of the first week of the next year.
7170         For example, <literal>2005-01-01</> is part of the 53rd week of year
7171         2004, and <literal>2006-01-01</> is part of the 52nd week of year
7172         2005, while <literal>2012-12-31</> is part of the first week of 2013.
7173         It's recommended to use the <literal>isoyear</> field together with
7174         <literal>week</> to get consistent results.
7175        </para>
7176
7177 <screen>
7178 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
7179 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
7180 </screen>
7181       </listitem>
7182      </varlistentry>
7183
7184      <varlistentry>
7185       <term><literal>year</literal></term>
7186       <listitem>
7187        <para>
7188         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting
7189         <literal>BC</> years from <literal>AD</> years should be done with care.
7190        </para>
7191
7192 <screen>
7193 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
7194 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
7195 </screen>
7196       </listitem>
7197      </varlistentry>
7198
7199     </variablelist>
7200    </para>
7201
7202    <para>
7203     The <function>extract</function> function is primarily intended
7204     for computational processing.  For formatting date/time values for
7205     display, see <xref linkend="functions-formatting">.
7206    </para>
7207
7208    <para>
7209     The <function>date_part</function> function is modeled on the traditional
7210     <productname>Ingres</productname> equivalent to the
7211     <acronym>SQL</acronym>-standard function <function>extract</function>:
7212 <synopsis>
7213 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
7214 </synopsis>
7215     Note that here the <replaceable>field</replaceable> parameter needs to
7216     be a string value, not a name.  The valid field names for
7217     <function>date_part</function> are the same as for
7218     <function>extract</function>.
7219    </para>
7220
7221 <screen>
7222 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
7223 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
7224
7225 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
7226 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
7227 </screen>
7228
7229   </sect2>
7230
7231   <sect2 id="functions-datetime-trunc">
7232    <title><function>date_trunc</function></title>
7233
7234    <indexterm>
7235     <primary>date_trunc</primary>
7236    </indexterm>
7237
7238    <para>
7239     The function <function>date_trunc</function> is conceptually
7240     similar to the <function>trunc</function> function for numbers.
7241    </para>
7242
7243    <para>
7244 <synopsis>
7245 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
7246 </synopsis>
7247     <replaceable>source</replaceable> is a value expression of type
7248     <type>timestamp</type> or <type>interval</>.
7249     (Values of type <type>date</type> and
7250     <type>time</type> are cast automatically to <type>timestamp</type> or
7251     <type>interval</>, respectively.)
7252     <replaceable>field</replaceable> selects to which precision to
7253     truncate the input value.  The return value is of type
7254     <type>timestamp</type> or <type>interval</>
7255     with all fields that are less significant than the
7256     selected one set to zero (or one, for day and month).
7257    </para>
7258
7259    <para>
7260     Valid values for <replaceable>field</replaceable> are:
7261     <simplelist>
7262      <member><literal>microseconds</literal></member>
7263      <member><literal>milliseconds</literal></member>
7264      <member><literal>second</literal></member>
7265      <member><literal>minute</literal></member>
7266      <member><literal>hour</literal></member>
7267      <member><literal>day</literal></member>
7268      <member><literal>week</literal></member>
7269      <member><literal>month</literal></member>
7270      <member><literal>quarter</literal></member>
7271      <member><literal>year</literal></member>
7272      <member><literal>decade</literal></member>
7273      <member><literal>century</literal></member>
7274      <member><literal>millennium</literal></member>
7275     </simplelist>
7276    </para>
7277
7278    <para>
7279     Examples:
7280 <screen>
7281 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
7282 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
7283
7284 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
7285 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
7286 </screen>
7287    </para>
7288   </sect2>
7289
7290   <sect2 id="functions-datetime-zoneconvert">
7291    <title><literal>AT TIME ZONE</literal></title>
7292
7293    <indexterm>
7294     <primary>time zone</primary>
7295     <secondary>conversion</secondary>
7296    </indexterm>
7297
7298    <indexterm>
7299     <primary>AT TIME ZONE</primary>
7300    </indexterm>
7301
7302    <para>
7303     The <literal>AT TIME ZONE</literal> construct allows conversions
7304     of time stamps to different time zones.  <xref
7305     linkend="functions-datetime-zoneconvert-table"> shows its
7306     variants.
7307    </para>
7308
7309     <table id="functions-datetime-zoneconvert-table">
7310      <title><literal>AT TIME ZONE</literal> Variants</title>
7311      <tgroup cols="3">
7312       <thead>
7313        <row>
7314         <entry>Expression</entry>
7315         <entry>Return Type</entry>
7316         <entry>Description</entry>
7317        </row>
7318       </thead>
7319
7320       <tbody>
7321        <row>
7322         <entry>
7323          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7324         </entry>
7325         <entry><type>timestamp with time zone</type></entry>
7326         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
7327        </row>
7328
7329        <row>
7330         <entry>
7331          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7332         </entry>
7333         <entry><type>timestamp without time zone</type></entry>
7334         <entry>Convert given time stamp <emphasis>with time zone</> to the new time
7335         zone, with no time zone designation</entry>
7336        </row>
7337
7338        <row>
7339         <entry>
7340          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7341         </entry>
7342         <entry><type>time with time zone</type></entry>
7343         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
7344        </row>
7345       </tbody>
7346      </tgroup>
7347     </table>
7348
7349    <para>
7350     In these expressions, the desired time zone <replaceable>zone</> can be
7351     specified either as a text string (e.g., <literal>'PST'</literal>)
7352     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
7353     In the text case, a time zone name can be specified in any of the ways
7354     described in <xref linkend="datatype-timezones">.
7355    </para>
7356
7357    <para>
7358     Examples (assuming the local time zone is <literal>PST8PDT</>):
7359 <screen>
7360 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
7361 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
7362
7363 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
7364 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
7365 </screen>
7366     The first example takes a time stamp without time zone and interprets it as MST time
7367     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes
7368     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
7369    </para>
7370
7371    <para>
7372     The function <literal><function>timezone</function>(<replaceable>zone</>,
7373     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
7374     <literal><replaceable>timestamp</> AT TIME ZONE
7375     <replaceable>zone</></literal>.
7376    </para>
7377   </sect2>
7378
7379   <sect2 id="functions-datetime-current">
7380    <title>Current Date/Time</title>
7381
7382    <indexterm>
7383     <primary>date</primary>
7384     <secondary>current</secondary>
7385    </indexterm>
7386
7387    <indexterm>
7388     <primary>time</primary>
7389     <secondary>current</secondary>
7390    </indexterm>
7391
7392    <para>
7393     <productname>PostgreSQL</productname> provides a number of functions
7394     that return values related to the current date and time.  These
7395     SQL-standard functions all return values based on the start time of
7396     the current transaction:
7397 <synopsis>
7398 CURRENT_DATE
7399 CURRENT_TIME
7400 CURRENT_TIMESTAMP
7401 CURRENT_TIME(<replaceable>precision</replaceable>)
7402 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
7403 LOCALTIME
7404 LOCALTIMESTAMP
7405 LOCALTIME(<replaceable>precision</replaceable>)
7406 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
7407 </synopsis>
7408     </para>
7409
7410     <para>
7411      <function>CURRENT_TIME</function> and
7412      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
7413      <function>LOCALTIME</function> and
7414      <function>LOCALTIMESTAMP</function> deliver values without time zone.
7415     </para>
7416
7417     <para>
7418      <function>CURRENT_TIME</function>,
7419      <function>CURRENT_TIMESTAMP</function>,
7420      <function>LOCALTIME</function>, and
7421      <function>LOCALTIMESTAMP</function>
7422      can optionally take
7423      a precision parameter, which causes the result to be rounded
7424      to that many fractional digits in the seconds field.  Without a precision parameter,
7425      the result is given to the full available precision.
7426     </para>
7427
7428    <para>
7429     Some examples:
7430 <screen>
7431 SELECT CURRENT_TIME;
7432 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
7433
7434 SELECT CURRENT_DATE;
7435 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
7436
7437 SELECT CURRENT_TIMESTAMP;
7438 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
7439
7440 SELECT CURRENT_TIMESTAMP(2);
7441 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
7442
7443 SELECT LOCALTIMESTAMP;
7444 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
7445 </screen>
7446    </para>
7447
7448    <para>
7449     Since these functions return
7450     the start time of the current transaction, their values do not
7451     change during the transaction. This is considered a feature:
7452     the intent is to allow a single transaction to have a consistent
7453     notion of the <quote>current</quote> time, so that multiple
7454     modifications within the same transaction bear the same
7455     time stamp.
7456    </para>
7457
7458    <note>
7459     <para>
7460      Other database systems might advance these values more
7461      frequently.
7462     </para>
7463    </note>
7464
7465    <para>
7466     <productname>PostgreSQL</productname> also provides functions that
7467     return the start time of the current statement, as well as the actual
7468     current time at the instant the function is called.  The complete list
7469     of non-SQL-standard time functions is:
7470 <synopsis>
7471 transaction_timestamp()
7472 statement_timestamp()
7473 clock_timestamp()
7474 timeofday()
7475 now()
7476 </synopsis>
7477    </para>
7478
7479    <para>
7480     <function>transaction_timestamp()</> is equivalent to
7481     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
7482     what it returns.
7483     <function>statement_timestamp()</> returns the start time of the current
7484     statement (more specifically, the time of receipt of the latest command
7485     message from the client).
7486     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
7487     return the same value during the first command of a transaction, but might
7488     differ during subsequent commands.
7489     <function>clock_timestamp()</> returns the actual current time, and
7490     therefore its value changes even within a single SQL command.
7491     <function>timeofday()</> is a historical
7492     <productname>PostgreSQL</productname> function.  Like
7493     <function>clock_timestamp()</>, it returns the actual current time,
7494     but as a formatted <type>text</> string rather than a <type>timestamp
7495     with time zone</> value.
7496     <function>now()</> is a traditional <productname>PostgreSQL</productname>
7497     equivalent to <function>transaction_timestamp()</function>.
7498    </para>
7499
7500    <para>
7501     All the date/time data types also accept the special literal value
7502     <literal>now</literal> to specify the current date and time (again,
7503     interpreted as the transaction start time).  Thus,
7504     the following three all return the same result:
7505 <programlisting>
7506 SELECT CURRENT_TIMESTAMP;
7507 SELECT now();
7508 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
7509 </programlisting>
7510    </para>
7511
7512     <tip>
7513      <para>
7514       You do not want to use the third form when specifying a <literal>DEFAULT</>
7515       clause while creating a table.  The system will convert <literal>now</literal>
7516       to a <type>timestamp</type> as soon as the constant is parsed, so that when
7517       the default value is needed,
7518       the time of the table creation would be used!  The first two
7519       forms will not be evaluated until the default value is used,
7520       because they are function calls.  Thus they will give the desired
7521       behavior of defaulting to the time of row insertion.
7522      </para>
7523     </tip>
7524   </sect2>
7525
7526   <sect2 id="functions-datetime-delay">
7527    <title>Delaying Execution</title>
7528
7529    <indexterm>
7530     <primary>pg_sleep</primary>
7531    </indexterm>
7532    <indexterm>
7533     <primary>sleep</primary>
7534    </indexterm>
7535    <indexterm>
7536     <primary>delay</primary>
7537    </indexterm>
7538
7539    <para>
7540     The following function is available to delay execution of the server
7541     process:
7542 <synopsis>
7543 pg_sleep(<replaceable>seconds</replaceable>)
7544 </synopsis>
7545
7546     <function>pg_sleep</function> makes the current session's process
7547     sleep until <replaceable>seconds</replaceable> seconds have
7548     elapsed.  <replaceable>seconds</replaceable> is a value of type
7549     <type>double precision</>, so fractional-second delays can be specified.
7550     For example:
7551
7552 <programlisting>
7553 SELECT pg_sleep(1.5);
7554 </programlisting>
7555    </para>
7556
7557    <note>
7558      <para>
7559       The effective resolution of the sleep interval is platform-specific;
7560       0.01 seconds is a common value.  The sleep delay will be at least as long
7561       as specified. It might be longer depending on factors such as server load.
7562      </para>
7563    </note>
7564
7565    <warning>
7566      <para>
7567       Make sure that your session does not hold more locks than necessary
7568       when calling <function>pg_sleep</function>.  Otherwise other sessions
7569       might have to wait for your sleeping process, slowing down the entire
7570       system.
7571      </para>
7572    </warning>
7573   </sect2>
7574
7575  </sect1>
7576
7577
7578  <sect1 id="functions-enum">
7579   <title>Enum Support Functions</title>
7580
7581   <para>
7582    For enum types (described in <xref linkend="datatype-enum">),
7583    there are several functions that allow cleaner programming without
7584    hard-coding particular values of an enum type.
7585    These are listed in <xref linkend="functions-enum-table">. The examples
7586    assume an enum type created as:
7587
7588 <programlisting>
7589 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
7590 </programlisting>
7591
7592   </para>
7593
7594   <table id="functions-enum-table">
7595     <title>Enum Support Functions</title>
7596     <tgroup cols="4">
7597      <thead>
7598       <row>
7599        <entry>Function</entry>
7600        <entry>Description</entry>
7601        <entry>Example</entry>
7602        <entry>Example Result</entry>
7603       </row>
7604      </thead>
7605      <tbody>
7606       <row>
7607        <entry>
7608          <indexterm>
7609           <primary>enum_first</primary>
7610          </indexterm>
7611          <literal>enum_first(anyenum)</literal>
7612        </entry>
7613        <entry>Returns the first value of the input enum type</entry>
7614        <entry><literal>enum_first(null::rainbow)</literal></entry>
7615        <entry><literal>red</literal></entry>
7616       </row>
7617       <row>
7618        <entry>
7619          <indexterm>
7620           <primary>enum_last</primary>
7621          </indexterm>
7622          <literal>enum_last(anyenum)</literal>
7623        </entry>
7624        <entry>Returns the last value of the input enum type</entry>
7625        <entry><literal>enum_last(null::rainbow)</literal></entry>
7626        <entry><literal>purple</literal></entry>
7627       </row>
7628       <row>
7629        <entry>
7630          <indexterm>
7631           <primary>enum_range</primary>
7632          </indexterm>
7633          <literal>enum_range(anyenum)</literal>
7634        </entry>
7635        <entry>Returns all values of the input enum type in an ordered array</entry>
7636        <entry><literal>enum_range(null::rainbow)</literal></entry>
7637        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
7638       </row>
7639       <row>
7640        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
7641        <entry morerows="2">
7642         Returns the range between the two given enum values, as an ordered
7643         array. The values must be from the same enum type. If the first
7644         parameter is null, the result will start with the first value of
7645         the enum type.
7646         If the second parameter is null, the result will end with the last
7647         value of the enum type.
7648        </entry>
7649        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
7650        <entry><literal>{orange,yellow,green}</literal></entry>
7651       </row>
7652       <row>
7653        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
7654        <entry><literal>{red,orange,yellow,green}</literal></entry>
7655       </row>
7656       <row>
7657        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
7658        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
7659       </row>
7660      </tbody>
7661     </tgroup>
7662    </table>
7663
7664    <para>
7665     Notice that except for the two-argument form of <function>enum_range</>,
7666     these functions disregard the specific value passed to them; they care
7667     only about its declared data type.  Either null or a specific value of
7668     the type can be passed, with the same result.  It is more common to
7669     apply these functions to a table column or function argument than to
7670     a hardwired type name as suggested by the examples.
7671    </para>
7672  </sect1>
7673
7674  <sect1 id="functions-geometry">
7675   <title>Geometric Functions and Operators</title>
7676
7677    <para>
7678     The geometric types <type>point</type>, <type>box</type>,
7679     <type>lseg</type>, <type>line</type>, <type>path</type>,
7680     <type>polygon</type>, and <type>circle</type> have a large set of
7681     native support functions and operators, shown in <xref
7682     linkend="functions-geometry-op-table">, <xref
7683     linkend="functions-geometry-func-table">, and <xref
7684     linkend="functions-geometry-conv-table">.
7685    </para>
7686
7687    <caution>
7688     <para>
7689      Note that the <quote>same as</> operator, <literal>~=</>, represents
7690      the usual notion of equality for the <type>point</type>,
7691      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
7692      Some of these types also have an <literal>=</> operator, but
7693      <literal>=</> compares
7694      for equal <emphasis>areas</> only.  The other scalar comparison operators
7695      (<literal>&lt;=</> and so on) likewise compare areas for these types.
7696     </para>
7697    </caution>
7698
7699    <table id="functions-geometry-op-table">
7700      <title>Geometric Operators</title>
7701      <tgroup cols="3">
7702       <thead>
7703        <row>
7704         <entry>Operator</entry>
7705         <entry>Description</entry>
7706         <entry>Example</entry>
7707        </row>
7708       </thead>
7709       <tbody>
7710        <row>
7711         <entry> <literal>+</literal> </entry>
7712         <entry>Translation</entry>
7713         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
7714        </row>
7715        <row>
7716         <entry> <literal>-</literal> </entry>
7717         <entry>Translation</entry>
7718         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
7719        </row>
7720        <row>
7721         <entry> <literal>*</literal> </entry>
7722         <entry>Scaling/rotation</entry>
7723         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
7724        </row>
7725        <row>
7726         <entry> <literal>/</literal> </entry>
7727         <entry>Scaling/rotation</entry>
7728         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
7729        </row>
7730        <row>
7731         <entry> <literal>#</literal> </entry>
7732         <entry>Point or box of intersection</entry>
7733         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
7734        </row>
7735        <row>
7736         <entry> <literal>#</literal> </entry>
7737         <entry>Number of points in path or polygon</entry>
7738         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
7739        </row>
7740        <row>
7741         <entry> <literal>@-@</literal> </entry>
7742         <entry>Length or circumference</entry>
7743         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
7744        </row>
7745        <row>
7746         <entry> <literal>@@</literal> </entry>
7747         <entry>Center</entry>
7748         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
7749        </row>
7750        <row>
7751         <entry> <literal>##</literal> </entry>
7752         <entry>Closest point to first operand on second operand</entry>
7753         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
7754        </row>
7755        <row>
7756         <entry> <literal>&lt;-&gt;</literal> </entry>
7757         <entry>Distance between</entry>
7758         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
7759        </row>
7760        <row>
7761         <entry> <literal>&amp;&amp;</literal> </entry>
7762         <entry>Overlaps?  (One point in common makes this true.)</entry>
7763         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
7764        </row>
7765        <row>
7766         <entry> <literal>&lt;&lt;</literal> </entry>
7767         <entry>Is strictly left of?</entry>
7768         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
7769        </row>
7770        <row>
7771         <entry> <literal>&gt;&gt;</literal> </entry>
7772         <entry>Is strictly right of?</entry>
7773         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
7774        </row>
7775        <row>
7776         <entry> <literal>&amp;&lt;</literal> </entry>
7777         <entry>Does not extend to the right of?</entry>
7778         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
7779        </row>
7780        <row>
7781         <entry> <literal>&amp;&gt;</literal> </entry>
7782         <entry>Does not extend to the left of?</entry>
7783         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
7784        </row>
7785        <row>
7786         <entry> <literal>&lt;&lt;|</literal> </entry>
7787         <entry>Is strictly below?</entry>
7788         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
7789        </row>
7790        <row>
7791         <entry> <literal>|&gt;&gt;</literal> </entry>
7792         <entry>Is strictly above?</entry>
7793         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
7794        </row>
7795        <row>
7796         <entry> <literal>&amp;&lt;|</literal> </entry>
7797         <entry>Does not extend above?</entry>
7798         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
7799        </row>
7800        <row>
7801         <entry> <literal>|&amp;&gt;</literal> </entry>
7802         <entry>Does not extend below?</entry>
7803         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
7804        </row>
7805        <row>
7806         <entry> <literal>&lt;^</literal> </entry>
7807         <entry>Is below (allows touching)?</entry>
7808         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
7809        </row>
7810        <row>
7811         <entry> <literal>&gt;^</literal> </entry>
7812         <entry>Is above (allows touching)?</entry>
7813         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
7814        </row>
7815        <row>
7816         <entry> <literal>?#</literal> </entry>
7817         <entry>Intersects?</entry>
7818         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7819        </row>
7820        <row>
7821         <entry> <literal>?-</literal> </entry>
7822         <entry>Is horizontal?</entry>
7823         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7824        </row>
7825        <row>
7826         <entry> <literal>?-</literal> </entry>
7827         <entry>Are horizontally aligned?</entry>
7828         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7829        </row>
7830        <row>
7831         <entry> <literal>?|</literal> </entry>
7832         <entry>Is vertical?</entry>
7833         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7834        </row>
7835        <row>
7836         <entry> <literal>?|</literal> </entry>
7837         <entry>Are vertically aligned?</entry>
7838         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7839        </row>
7840        <row>
7841         <entry> <literal>?-|</literal> </entry>
7842         <entry>Is perpendicular?</entry>
7843         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7844        </row>
7845        <row>
7846         <entry> <literal>?||</literal> </entry>
7847         <entry>Are parallel?</entry>
7848         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7849        </row>
7850        <row>
7851         <entry> <literal>@&gt;</literal> </entry>
7852         <entry>Contains?</entry>
7853         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7854        </row>
7855        <row>
7856         <entry> <literal>&lt;@</literal> </entry>
7857         <entry>Contained in or on?</entry>
7858         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7859        </row>
7860        <row>
7861         <entry> <literal>~=</literal> </entry>
7862         <entry>Same as?</entry>
7863         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7864        </row>
7865       </tbody>
7866      </tgroup>
7867    </table>
7868
7869    <note>
7870     <para>
7871      Before <productname>PostgreSQL</productname> 8.2, the containment
7872      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7873      called <literal>~</> and <literal>@</>.  These names are still
7874      available, but are deprecated and will eventually be removed.
7875     </para>
7876    </note>
7877
7878    <indexterm>
7879     <primary>area</primary>
7880    </indexterm>
7881    <indexterm>
7882     <primary>center</primary>
7883    </indexterm>
7884    <indexterm>
7885     <primary>diameter</primary>
7886    </indexterm>
7887    <indexterm>
7888     <primary>height</primary>
7889    </indexterm>
7890    <indexterm>
7891     <primary>isclosed</primary>
7892    </indexterm>
7893    <indexterm>
7894     <primary>isopen</primary>
7895    </indexterm>
7896    <indexterm>
7897     <primary>length</primary>
7898    </indexterm>
7899    <indexterm>
7900     <primary>npoints</primary>
7901    </indexterm>
7902    <indexterm>
7903     <primary>pclose</primary>
7904    </indexterm>
7905    <indexterm>
7906     <primary>popen</primary>
7907    </indexterm>
7908    <indexterm>
7909     <primary>radius</primary>
7910    </indexterm>
7911    <indexterm>
7912     <primary>width</primary>
7913    </indexterm>
7914
7915    <table id="functions-geometry-func-table">
7916      <title>Geometric Functions</title>
7917      <tgroup cols="4">
7918       <thead>
7919        <row>
7920         <entry>Function</entry>
7921         <entry>Return Type</entry>
7922         <entry>Description</entry>
7923         <entry>Example</entry>
7924        </row>
7925       </thead>
7926       <tbody>
7927        <row>
7928         <entry><literal><function>area(<replaceable>object</>)</function></literal></entry>
7929         <entry><type>double precision</type></entry>
7930         <entry>area</entry>
7931         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7932        </row>
7933        <row>
7934         <entry><literal><function>center(<replaceable>object</>)</function></literal></entry>
7935         <entry><type>point</type></entry>
7936         <entry>center</entry>
7937         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7938        </row>
7939        <row>
7940         <entry><literal><function>diameter(<type>circle</>)</function></literal></entry>
7941         <entry><type>double precision</type></entry>
7942         <entry>diameter of circle</entry>
7943         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7944        </row>
7945        <row>
7946         <entry><literal><function>height(<type>box</>)</function></literal></entry>
7947         <entry><type>double precision</type></entry>
7948         <entry>vertical size of box</entry>
7949         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7950        </row>
7951        <row>
7952         <entry><literal><function>isclosed(<type>path</>)</function></literal></entry>
7953         <entry><type>boolean</type></entry>
7954         <entry>a closed path?</entry>
7955         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7956        </row>
7957        <row>
7958         <entry><literal><function>isopen(<type>path</>)</function></literal></entry>
7959         <entry><type>boolean</type></entry>
7960         <entry>an open path?</entry>
7961         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7962        </row>
7963        <row>
7964         <entry><literal><function>length(<replaceable>object</>)</function></literal></entry>
7965         <entry><type>double precision</type></entry>
7966         <entry>length</entry>
7967         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7968        </row>
7969        <row>
7970         <entry><literal><function>npoints(<type>path</>)</function></literal></entry>
7971         <entry><type>int</type></entry>
7972         <entry>number of points</entry>
7973         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7974        </row>
7975        <row>
7976         <entry><literal><function>npoints(<type>polygon</>)</function></literal></entry>
7977         <entry><type>int</type></entry>
7978         <entry>number of points</entry>
7979         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7980        </row>
7981        <row>
7982         <entry><literal><function>pclose(<type>path</>)</function></literal></entry>
7983         <entry><type>path</type></entry>
7984         <entry>convert path to closed</entry>
7985         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7986        </row>
7987 <![IGNORE[
7988 <!-- Not defined by this name. Implements the intersection operator '#' -->
7989        <row>
7990         <entry><literal><function>point(<type>lseg</>, <type>lseg</>)</function></literal></entry>
7991         <entry><type>point</type></entry>
7992         <entry>intersection</entry>
7993         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7994        </row>
7995 ]]>
7996        <row>
7997         <entry><literal><function>popen(<type>path</>)</function></literal></entry>
7998         <entry><type>path</type></entry>
7999         <entry>convert path to open</entry>
8000         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
8001        </row>
8002        <row>
8003         <entry><literal><function>radius(<type>circle</type>)</function></literal></entry>
8004         <entry><type>double precision</type></entry>
8005         <entry>radius of circle</entry>
8006         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
8007        </row>
8008        <row>
8009         <entry><literal><function>width(<type>box</>)</function></literal></entry>
8010         <entry><type>double precision</type></entry>
8011         <entry>horizontal size of box</entry>
8012         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
8013        </row>
8014       </tbody>
8015      </tgroup>
8016    </table>
8017
8018    <table id="functions-geometry-conv-table">
8019      <title>Geometric Type Conversion Functions</title>
8020      <tgroup cols="4">
8021       <thead>
8022        <row>
8023         <entry>Function</entry>
8024         <entry>Return Type</entry>
8025         <entry>Description</entry>
8026         <entry>Example</entry>
8027        </row>
8028       </thead>
8029       <tbody>
8030        <row>
8031         <entry>
8032          <indexterm>
8033           <primary>box</primary>
8034          </indexterm>
8035          <literal><function>box(<type>circle</type>)</function></literal>
8036         </entry>
8037         <entry><type>box</type></entry>
8038         <entry>circle to box</entry>
8039         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
8040        </row>
8041        <row>
8042         <entry><literal><function>box(<type>point</type>, <type>point</type>)</function></literal></entry>
8043         <entry><type>box</type></entry>
8044         <entry>points to box</entry>
8045         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
8046        </row>
8047        <row>
8048         <entry><literal><function>box(<type>polygon</type>)</function></literal></entry>
8049         <entry><type>box</type></entry>
8050         <entry>polygon to box</entry>
8051         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8052        </row>
8053        <row>
8054         <entry>
8055          <indexterm>
8056           <primary>circle</primary>
8057          </indexterm>
8058          <literal><function>circle(<type>box</type>)</function></literal>
8059         </entry>
8060         <entry><type>circle</type></entry>
8061         <entry>box to circle</entry>
8062         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
8063        </row>
8064        <row>
8065         <entry><literal><function>circle(<type>point</type>, <type>double precision</type>)</function></literal></entry>
8066         <entry><type>circle</type></entry>
8067         <entry>center and radius to circle</entry>
8068         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
8069        </row>
8070        <row>
8071         <entry><literal><function>circle(<type>polygon</type>)</function></literal></entry>
8072         <entry><type>circle</type></entry>
8073         <entry>polygon to circle</entry>
8074         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8075        </row>
8076        <row>
8077         <entry>
8078          <indexterm>
8079           <primary>lseg</primary>
8080          </indexterm>
8081          <literal><function>lseg(<type>box</type>)</function></literal>
8082         </entry>
8083         <entry><type>lseg</type></entry>
8084         <entry>box diagonal to line segment</entry>
8085         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
8086        </row>
8087        <row>
8088         <entry><literal><function>lseg(<type>point</type>, <type>point</type>)</function></literal></entry>
8089         <entry><type>lseg</type></entry>
8090         <entry>points to line segment</entry>
8091         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
8092        </row>
8093        <row>
8094         <entry>
8095          <indexterm>
8096           <primary>path</primary>
8097          </indexterm>
8098          <literal><function>path(<type>polygon</type>)</function></literal>
8099         </entry>
8100         <entry><type>path</type></entry>
8101         <entry>polygon to path</entry>
8102         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8103        </row>
8104        <row>
8105         <entry>
8106          <indexterm>
8107           <primary>point</primary>
8108          </indexterm>
8109          <literal><function>point</function>(<type>double
8110          precision</type>, <type>double precision</type>)</literal>
8111         </entry>
8112         <entry><type>point</type></entry>
8113         <entry>construct point</entry>
8114         <entry><literal>point(23.4, -44.5)</literal></entry>
8115        </row>
8116        <row>
8117         <entry><literal><function>point(<type>box</type>)</function></literal></entry>
8118         <entry><type>point</type></entry>
8119         <entry>center of box</entry>
8120         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
8121        </row>
8122        <row>
8123         <entry><literal><function>point(<type>circle</type>)</function></literal></entry>
8124         <entry><type>point</type></entry>
8125         <entry>center of circle</entry>
8126         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
8127        </row>
8128        <row>
8129         <entry><literal><function>point(<type>lseg</type>)</function></literal></entry>
8130         <entry><type>point</type></entry>
8131         <entry>center of line segment</entry>
8132         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
8133        </row>
8134        <row>
8135         <entry><literal><function>point(<type>polygon</type>)</function></literal></entry>
8136         <entry><type>point</type></entry>
8137         <entry>center of polygon</entry>
8138         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8139        </row>
8140        <row>
8141         <entry>
8142          <indexterm>
8143           <primary>polygon</primary>
8144          </indexterm>
8145          <literal><function>polygon(<type>box</type>)</function></literal>
8146         </entry>
8147         <entry><type>polygon</type></entry>
8148         <entry>box to 4-point polygon</entry>
8149         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
8150        </row>
8151        <row>
8152         <entry><literal><function>polygon(<type>circle</type>)</function></literal></entry>
8153         <entry><type>polygon</type></entry>
8154         <entry>circle to 12-point polygon</entry>
8155         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
8156        </row>
8157        <row>
8158         <entry><literal><function>polygon(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</function></literal></entry>
8159         <entry><type>polygon</type></entry>
8160         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
8161         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
8162        </row>
8163        <row>
8164         <entry><literal><function>polygon(<type>path</type>)</function></literal></entry>
8165         <entry><type>polygon</type></entry>
8166         <entry>path to polygon</entry>
8167         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
8168        </row>
8169       </tbody>
8170      </tgroup>
8171    </table>
8172
8173     <para>
8174      It is possible to access the two component numbers of a <type>point</>
8175      as though the point were an array with indexes 0 and 1.  For example, if
8176      <literal>t.p</> is a <type>point</> column then
8177      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
8178      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
8179      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
8180      as an array of two <type>point</> values.
8181     </para>
8182
8183     <para>
8184      The <function>area</function> function works for the types
8185      <type>box</type>, <type>circle</type>, and <type>path</type>.
8186      The <function>area</function> function only works on the
8187      <type>path</type> data type if the points in the
8188      <type>path</type> are non-intersecting.  For example, the
8189      <type>path</type>
8190      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
8191      will not work;  however, the following visually identical
8192      <type>path</type>
8193      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
8194      will work.  If the concept of an intersecting versus
8195      non-intersecting <type>path</type> is confusing, draw both of the
8196      above <type>path</type>s side by side on a piece of graph paper.
8197     </para>
8198
8199   </sect1>
8200
8201
8202  <sect1 id="functions-net">
8203   <title>Network Address Functions and Operators</title>
8204
8205   <para>
8206    <xref linkend="cidr-inet-operators-table"> shows the operators
8207    available for the <type>cidr</type> and <type>inet</type> types.
8208    The operators <literal>&lt;&lt;</literal>,
8209    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
8210    <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
8211    consider only the network parts of the two addresses (ignoring any
8212    host part) and determine whether one network is identical to
8213    or a subnet of the other.
8214   </para>
8215
8216     <table id="cidr-inet-operators-table">
8217      <title><type>cidr</type> and <type>inet</type> Operators</title>
8218      <tgroup cols="3">
8219       <thead>
8220        <row>
8221         <entry>Operator</entry>
8222         <entry>Description</entry>
8223         <entry>Example</entry>
8224        </row>
8225       </thead>
8226       <tbody>
8227        <row>
8228         <entry> <literal>&lt;</literal> </entry>
8229         <entry>is less than</entry>
8230         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
8231        </row>
8232        <row>
8233         <entry> <literal>&lt;=</literal> </entry>
8234         <entry>is less than or equal</entry>
8235         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
8236        </row>
8237        <row>
8238         <entry> <literal>=</literal> </entry>
8239         <entry>equals</entry>
8240         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
8241        </row>
8242        <row>
8243         <entry> <literal>&gt;=</literal> </entry>
8244         <entry>is greater or equal</entry>
8245         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
8246        </row>
8247        <row>
8248         <entry> <literal>&gt;</literal> </entry>
8249         <entry>is greater than</entry>
8250         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
8251        </row>
8252        <row>
8253         <entry> <literal>&lt;&gt;</literal> </entry>
8254         <entry>is not equal</entry>
8255         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
8256        </row>
8257        <row>
8258         <entry> <literal>&lt;&lt;</literal> </entry>
8259         <entry>is contained within</entry>
8260         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
8261        </row>
8262        <row>
8263         <entry> <literal>&lt;&lt;=</literal> </entry>
8264         <entry>is contained within or equals</entry>
8265         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
8266        </row>
8267        <row>
8268         <entry> <literal>&gt;&gt;</literal> </entry>
8269         <entry>contains</entry>
8270         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
8271        </row>
8272        <row>
8273         <entry> <literal>&gt;&gt;=</literal> </entry>
8274         <entry>contains or equals</entry>
8275         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
8276        </row>
8277        <row>
8278         <entry> <literal>~</literal> </entry>
8279         <entry>bitwise NOT</entry>
8280         <entry><literal>~ inet '192.168.1.6'</literal></entry>
8281        </row>
8282        <row>
8283         <entry> <literal>&amp;</literal> </entry>
8284         <entry>bitwise AND</entry>
8285         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
8286        </row>
8287        <row>
8288         <entry> <literal>|</literal> </entry>
8289         <entry>bitwise OR</entry>
8290         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
8291        </row>
8292        <row>
8293         <entry> <literal>+</literal> </entry>
8294         <entry>addition</entry>
8295         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
8296        </row>
8297        <row>
8298         <entry> <literal>-</literal> </entry>
8299         <entry>subtraction</entry>
8300         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
8301        </row>
8302        <row>
8303         <entry> <literal>-</literal> </entry>
8304         <entry>subtraction</entry>
8305         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
8306        </row>
8307       </tbody>
8308      </tgroup>
8309     </table>
8310
8311   <para>
8312    <xref linkend="cidr-inet-functions-table"> shows the functions
8313    available for use with the <type>cidr</type> and <type>inet</type>
8314    types.  The <function>abbrev</function>, <function>host</function>,
8315    and <function>text</function>
8316    functions are primarily intended to offer alternative display
8317    formats.
8318   </para>
8319
8320     <table id="cidr-inet-functions-table">
8321      <title><type>cidr</type> and <type>inet</type> Functions</title>
8322      <tgroup cols="5">
8323       <thead>
8324        <row>
8325         <entry>Function</entry>
8326         <entry>Return Type</entry>
8327         <entry>Description</entry>
8328         <entry>Example</entry>
8329         <entry>Result</entry>
8330        </row>
8331       </thead>
8332       <tbody>
8333        <row>
8334         <entry>
8335          <indexterm>
8336           <primary>abbrev</primary>
8337          </indexterm>
8338          <literal><function>abbrev(<type>inet</type>)</function></literal>
8339         </entry>
8340         <entry><type>text</type></entry>
8341         <entry>abbreviated display format as text</entry>
8342         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
8343         <entry><literal>10.1.0.0/16</literal></entry>
8344        </row>
8345        <row>
8346         <entry><literal><function>abbrev(<type>cidr</type>)</function></literal></entry>
8347         <entry><type>text</type></entry>
8348         <entry>abbreviated display format as text</entry>
8349         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
8350         <entry><literal>10.1/16</literal></entry>
8351        </row>
8352        <row>
8353         <entry>
8354          <indexterm>
8355           <primary>broadcast</primary>
8356          </indexterm>
8357          <literal><function>broadcast(<type>inet</type>)</function></literal>
8358         </entry>
8359         <entry><type>inet</type></entry>
8360         <entry>broadcast address for network</entry>
8361         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
8362         <entry><literal>192.168.1.255/24</literal></entry>
8363        </row>
8364        <row>
8365         <entry>
8366          <indexterm>
8367           <primary>family</primary>
8368          </indexterm>
8369          <literal><function>family(<type>inet</type>)</function></literal>
8370         </entry>
8371         <entry><type>int</type></entry>
8372         <entry>extract family of address; <literal>4</literal> for IPv4,
8373          <literal>6</literal> for IPv6</entry>
8374         <entry><literal>family('::1')</literal></entry>
8375         <entry><literal>6</literal></entry>
8376        </row>
8377        <row>
8378         <entry>
8379          <indexterm>
8380           <primary>host</primary>
8381          </indexterm>
8382          <literal><function>host(<type>inet</type>)</function></literal>
8383         </entry>
8384         <entry><type>text</type></entry>
8385         <entry>extract IP address as text</entry>
8386         <entry><literal>host('192.168.1.5/24')</literal></entry>
8387         <entry><literal>192.168.1.5</literal></entry>
8388        </row>
8389        <row>
8390         <entry>
8391          <indexterm>
8392           <primary>hostmask</primary>
8393          </indexterm>
8394          <literal><function>hostmask(<type>inet</type>)</function></literal>
8395         </entry>
8396         <entry><type>inet</type></entry>
8397         <entry>construct host mask for network</entry>
8398         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
8399         <entry><literal>0.0.0.3</literal></entry>
8400        </row>
8401        <row>
8402         <entry>
8403          <indexterm>
8404           <primary>masklen</primary>
8405          </indexterm>
8406          <literal><function>masklen(<type>inet</type>)</function></literal>
8407         </entry>
8408         <entry><type>int</type></entry>
8409         <entry>extract netmask length</entry>
8410         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
8411         <entry><literal>24</literal></entry>
8412        </row>
8413        <row>
8414         <entry>
8415          <indexterm>
8416           <primary>netmask</primary>
8417          </indexterm>
8418          <literal><function>netmask(<type>inet</type>)</function></literal>
8419         </entry>
8420         <entry><type>inet</type></entry>
8421         <entry>construct netmask for network</entry>
8422         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
8423         <entry><literal>255.255.255.0</literal></entry>
8424        </row>
8425        <row>
8426         <entry>
8427          <indexterm>
8428           <primary>network</primary>
8429          </indexterm>
8430          <literal><function>network(<type>inet</type>)</function></literal>
8431         </entry>
8432         <entry><type>cidr</type></entry>
8433         <entry>extract network part of address</entry>
8434         <entry><literal>network('192.168.1.5/24')</literal></entry>
8435         <entry><literal>192.168.1.0/24</literal></entry>
8436        </row>
8437        <row>
8438         <entry>
8439          <indexterm>
8440           <primary>set_masklen</primary>
8441          </indexterm>
8442          <literal><function>set_masklen(<type>inet</type>, <type>int</type>)</function></literal>
8443         </entry>
8444         <entry><type>inet</type></entry>
8445         <entry>set netmask length for <type>inet</type> value</entry>
8446         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
8447         <entry><literal>192.168.1.5/16</literal></entry>
8448        </row>
8449        <row>
8450         <entry><literal><function>set_masklen(<type>cidr</type>, <type>int</type>)</function></literal></entry>
8451         <entry><type>cidr</type></entry>
8452         <entry>set netmask length for <type>cidr</type> value</entry>
8453         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
8454         <entry><literal>192.168.0.0/16</literal></entry>
8455        </row>
8456        <row>
8457         <entry>
8458          <indexterm>
8459           <primary>text</primary>
8460          </indexterm>
8461          <literal><function>text(<type>inet</type>)</function></literal>
8462         </entry>
8463         <entry><type>text</type></entry>
8464         <entry>extract IP address and netmask length as text</entry>
8465         <entry><literal>text(inet '192.168.1.5')</literal></entry>
8466         <entry><literal>192.168.1.5/32</literal></entry>
8467        </row>
8468       </tbody>
8469      </tgroup>
8470     </table>
8471
8472   <para>
8473    Any <type>cidr</> value can be cast to <type>inet</> implicitly
8474    or explicitly; therefore, the functions shown above as operating on
8475    <type>inet</> also work on <type>cidr</> values.  (Where there are
8476    separate functions for <type>inet</> and <type>cidr</>, it is because
8477    the behavior should be different for the two cases.)
8478    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
8479    When this is done, any bits to the right of the netmask are silently zeroed
8480    to create a valid <type>cidr</> value.
8481    In addition,
8482    you can cast a text value to <type>inet</> or <type>cidr</>
8483    using normal casting syntax: for example,
8484    <literal>inet(<replaceable>expression</>)</literal> or
8485    <literal><replaceable>colname</>::cidr</literal>.
8486   </para>
8487
8488   <para>
8489    <xref linkend="macaddr-functions-table"> shows the functions
8490    available for use with the <type>macaddr</type> type.  The function
8491    <literal><function>trunc(<type>macaddr</type>)</function></literal> returns a MAC
8492    address with the last 3 bytes set to zero.  This can be used to
8493    associate the remaining prefix with a manufacturer.
8494   </para>
8495
8496     <table id="macaddr-functions-table">
8497      <title><type>macaddr</type> Functions</title>
8498      <tgroup cols="5">
8499       <thead>
8500        <row>
8501         <entry>Function</entry>
8502         <entry>Return Type</entry>
8503         <entry>Description</entry>
8504         <entry>Example</entry>
8505         <entry>Result</entry>
8506        </row>
8507       </thead>
8508       <tbody>
8509        <row>
8510         <entry>
8511          <indexterm>
8512           <primary>trunc</primary>
8513          </indexterm>
8514          <literal><function>trunc(<type>macaddr</type>)</function></literal>
8515         </entry>
8516         <entry><type>macaddr</type></entry>
8517         <entry>set last 3 bytes to zero</entry>
8518         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
8519         <entry><literal>12:34:56:00:00:00</literal></entry>
8520        </row>
8521       </tbody>
8522      </tgroup>
8523     </table>
8524
8525    <para>
8526     The <type>macaddr</type> type also supports the standard relational
8527     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
8528     lexicographical ordering, and the bitwise arithmetic operators
8529     (<literal>~</literal>, <literal>&amp;</literal> and <literal>|</literal>)
8530     for NOT, AND and OR.
8531    </para>
8532
8533   </sect1>
8534
8535
8536  <sect1 id="functions-textsearch">
8537   <title>Text Search Functions and Operators</title>
8538
8539    <indexterm zone="datatype-textsearch">
8540     <primary>full text search</primary>
8541     <secondary>functions and operators</secondary>
8542    </indexterm>
8543
8544    <indexterm zone="datatype-textsearch">
8545     <primary>text search</primary>
8546     <secondary>functions and operators</secondary>
8547    </indexterm>
8548
8549   <para>
8550    <xref linkend="textsearch-operators-table">,
8551    <xref linkend="textsearch-functions-table"> and
8552    <xref linkend="textsearch-functions-debug-table">
8553    summarize the functions and operators that are provided
8554    for full text searching.  See <xref linkend="textsearch"> for a detailed
8555    explanation of <productname>PostgreSQL</productname>'s text search
8556    facility.
8557   </para>
8558
8559     <table id="textsearch-operators-table">
8560      <title>Text Search Operators</title>
8561      <tgroup cols="4">
8562       <thead>
8563        <row>
8564         <entry>Operator</entry>
8565         <entry>Description</entry>
8566         <entry>Example</entry>
8567         <entry>Result</entry>
8568        </row>
8569       </thead>
8570       <tbody>
8571        <row>
8572         <entry> <literal>@@</literal> </entry>
8573         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
8574         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
8575         <entry><literal>t</literal></entry>
8576        </row>
8577        <row>
8578         <entry> <literal>@@@</literal> </entry>
8579         <entry>deprecated synonym for <literal>@@</></entry>
8580         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
8581         <entry><literal>t</literal></entry>
8582        </row>
8583        <row>
8584         <entry> <literal>||</literal> </entry>
8585         <entry>concatenate <type>tsvector</>s</entry>
8586         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
8587         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
8588        </row>
8589        <row>
8590         <entry> <literal>&amp;&amp;</literal> </entry>
8591         <entry>AND <type>tsquery</>s together</entry>
8592         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
8593         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
8594        </row>
8595        <row>
8596         <entry> <literal>||</literal> </entry>
8597         <entry>OR <type>tsquery</>s together</entry>
8598         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
8599         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
8600        </row>
8601        <row>
8602         <entry> <literal>!!</literal> </entry>
8603         <entry>negate a <type>tsquery</></entry>
8604         <entry><literal>!! 'cat'::tsquery</literal></entry>
8605         <entry><literal>!'cat'</literal></entry>
8606        </row>
8607        <row>
8608         <entry> <literal>@&gt;</literal> </entry>
8609         <entry><type>tsquery</> contains another ?</entry>
8610         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
8611         <entry><literal>f</literal></entry>
8612        </row>
8613        <row>
8614         <entry> <literal>&lt;@</literal> </entry>
8615         <entry><type>tsquery</> is contained in ?</entry>
8616         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
8617         <entry><literal>t</literal></entry>
8618        </row>
8619       </tbody>
8620      </tgroup>
8621     </table>
8622
8623     <note>
8624      <para>
8625       The <type>tsquery</> containment operators consider only the lexemes
8626       listed in the two queries, ignoring the combining operators.
8627      </para>
8628     </note>
8629
8630     <para>
8631      In addition to the operators shown in the table, the ordinary B-tree
8632      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
8633      for types <type>tsvector</> and <type>tsquery</>.  These are not very
8634      useful for text searching but allow, for example, unique indexes to be
8635      built on columns of these types.
8636     </para>
8637
8638     <table id="textsearch-functions-table">
8639      <title>Text Search Functions</title>
8640      <tgroup cols="5">
8641       <thead>
8642        <row>
8643         <entry>Function</entry>
8644         <entry>Return Type</entry>
8645         <entry>Description</entry>
8646         <entry>Example</entry>
8647         <entry>Result</entry>
8648        </row>
8649       </thead>
8650       <tbody>
8651        <row>
8652         <entry>
8653          <indexterm>
8654           <primary>get_current_ts_config</primary>
8655          </indexterm>
8656          <literal><function>get_current_ts_config()</function></literal>
8657         </entry>
8658         <entry><type>regconfig</type></entry>
8659         <entry>get default text search configuration</entry>
8660         <entry><literal>get_current_ts_config()</literal></entry>
8661         <entry><literal>english</literal></entry>
8662        </row>
8663        <row>
8664         <entry>
8665          <indexterm>
8666           <primary>length</primary>
8667          </indexterm>
8668          <literal><function>length(<type>tsvector</>)</function></literal>
8669         </entry>
8670         <entry><type>integer</type></entry>
8671         <entry>number of lexemes in <type>tsvector</></entry>
8672         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
8673         <entry><literal>3</literal></entry>
8674        </row>
8675        <row>
8676         <entry>
8677          <indexterm>
8678           <primary>numnode</primary>
8679          </indexterm>
8680          <literal><function>numnode(<type>tsquery</>)</function></literal>
8681         </entry>
8682         <entry><type>integer</type></entry>
8683         <entry>number of lexemes plus operators in <type>tsquery</></entry>
8684         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
8685         <entry><literal>5</literal></entry>
8686        </row>
8687        <row>
8688         <entry>
8689          <indexterm>
8690           <primary>plainto_tsquery</primary>
8691          </indexterm>
8692          <literal><function>plainto_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
8693         </entry>
8694         <entry><type>tsquery</type></entry>
8695         <entry>produce <type>tsquery</> ignoring punctuation</entry>
8696         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
8697         <entry><literal>'fat' &amp; 'rat'</literal></entry>
8698        </row>
8699        <row>
8700         <entry>
8701          <indexterm>
8702           <primary>querytree</primary>
8703          </indexterm>
8704          <literal><function>querytree(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</function></literal>
8705         </entry>
8706         <entry><type>text</type></entry>
8707         <entry>get indexable part of a <type>tsquery</></entry>
8708         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
8709         <entry><literal>'foo'</literal></entry>
8710        </row>
8711        <row>
8712         <entry>
8713          <indexterm>
8714           <primary>setweight</primary>
8715          </indexterm>
8716          <literal><function>setweight(<type>tsvector</>, <type>"char"</>)</function></literal>
8717         </entry>
8718         <entry><type>tsvector</type></entry>
8719         <entry>assign weight to each element of <type>tsvector</></entry>
8720         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
8721         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
8722        </row>
8723        <row>
8724         <entry>
8725          <indexterm>
8726           <primary>strip</primary>
8727          </indexterm>
8728          <literal><function>strip(<type>tsvector</>)</function></literal>
8729         </entry>
8730         <entry><type>tsvector</type></entry>
8731         <entry>remove positions and weights from <type>tsvector</></entry>
8732         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
8733         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
8734        </row>
8735        <row>
8736         <entry>
8737          <indexterm>
8738           <primary>to_tsquery</primary>
8739          </indexterm>
8740          <literal><function>to_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
8741         </entry>
8742         <entry><type>tsquery</type></entry>
8743         <entry>normalize words and convert to <type>tsquery</></entry>
8744         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
8745         <entry><literal>'fat' &amp; 'rat'</literal></entry>
8746        </row>
8747        <row>
8748         <entry>
8749          <indexterm>
8750           <primary>to_tsvector</primary>
8751          </indexterm>
8752          <literal><function>to_tsvector(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</function></literal>
8753         </entry>
8754         <entry><type>tsvector</type></entry>
8755         <entry>reduce document text to <type>tsvector</></entry>
8756         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
8757         <entry><literal>'fat':2 'rat':3</literal></entry>
8758        </row>
8759        <row>
8760         <entry>
8761          <indexterm>
8762           <primary>ts_headline</primary>
8763          </indexterm>
8764          <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>
8765         </entry>
8766         <entry><type>text</type></entry>
8767         <entry>display a query match</entry>
8768         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
8769         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
8770        </row>
8771        <row>
8772         <entry>
8773          <indexterm>
8774           <primary>ts_rank</primary>
8775          </indexterm>
8776          <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>
8777         </entry>
8778         <entry><type>float4</type></entry>
8779         <entry>rank document for query</entry>
8780         <entry><literal>ts_rank(textsearch, query)</literal></entry>
8781         <entry><literal>0.818</literal></entry>
8782        </row>
8783        <row>
8784         <entry>
8785          <indexterm>
8786           <primary>ts_rank_cd</primary>
8787          </indexterm>
8788          <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>
8789         </entry>
8790         <entry><type>float4</type></entry>
8791         <entry>rank document for query using cover density</entry>
8792         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
8793         <entry><literal>2.01317</literal></entry>
8794        </row>
8795        <row>
8796         <entry>
8797          <indexterm>
8798           <primary>ts_rewrite</primary>
8799          </indexterm>
8800          <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>
8801         </entry>
8802         <entry><type>tsquery</type></entry>
8803         <entry>replace target with substitute within query</entry>
8804         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
8805         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
8806        </row>
8807        <row>
8808         <entry><literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</function></literal></entry>
8809         <entry><type>tsquery</type></entry>
8810         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
8811         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
8812         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
8813        </row>
8814        <row>
8815         <entry>
8816          <indexterm>
8817           <primary>tsvector_update_trigger</primary>
8818          </indexterm>
8819          <literal><function>tsvector_update_trigger()</function></literal>
8820         </entry>
8821         <entry><type>trigger</type></entry>
8822         <entry>trigger function for automatic <type>tsvector</> column update</entry>
8823         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
8824         <entry><literal></literal></entry>
8825        </row>
8826        <row>
8827         <entry>
8828          <indexterm>
8829           <primary>tsvector_update_trigger_column</primary>
8830          </indexterm>
8831          <literal><function>tsvector_update_trigger_column()</function></literal>
8832         </entry>
8833         <entry><type>trigger</type></entry>
8834         <entry>trigger function for automatic <type>tsvector</> column update</entry>
8835         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
8836         <entry><literal></literal></entry>
8837        </row>
8838       </tbody>
8839      </tgroup>
8840     </table>
8841
8842   <note>
8843    <para>
8844     All the text search functions that accept an optional <type>regconfig</>
8845     argument will use the configuration specified by
8846     <xref linkend="guc-default-text-search-config">
8847     when that argument is omitted.
8848    </para>
8849   </note>
8850
8851   <para>
8852    The functions in
8853    <xref linkend="textsearch-functions-debug-table">
8854    are listed separately because they are not usually used in everyday text
8855    searching operations.  They are helpful for development and debugging
8856    of new text search configurations.
8857   </para>
8858
8859     <table id="textsearch-functions-debug-table">
8860      <title>Text Search Debugging Functions</title>
8861      <tgroup cols="5">
8862       <thead>
8863        <row>
8864         <entry>Function</entry>
8865         <entry>Return Type</entry>
8866         <entry>Description</entry>
8867         <entry>Example</entry>
8868         <entry>Result</entry>
8869        </row>
8870       </thead>
8871       <tbody>
8872        <row>
8873         <entry>
8874          <indexterm>
8875           <primary>ts_debug</primary>
8876          </indexterm>
8877          <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>
8878         </entry>
8879         <entry><type>setof record</type></entry>
8880         <entry>test a configuration</entry>
8881         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
8882         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
8883        </row>
8884        <row>
8885         <entry>
8886          <indexterm>
8887           <primary>ts_lexize</primary>
8888          </indexterm>
8889          <literal><function>ts_lexize(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</function></literal>
8890         </entry>
8891         <entry><type>text[]</type></entry>
8892         <entry>test a dictionary</entry>
8893         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
8894         <entry><literal>{star}</literal></entry>
8895        </row>
8896        <row>
8897         <entry>
8898          <indexterm>
8899           <primary>ts_parse</primary>
8900          </indexterm>
8901          <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>
8902         </entry>
8903         <entry><type>setof record</type></entry>
8904         <entry>test a parser</entry>
8905         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
8906         <entry><literal>(1,foo) ...</literal></entry>
8907        </row>
8908        <row>
8909         <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>
8910         <entry><type>setof record</type></entry>
8911         <entry>test a parser</entry>
8912         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
8913         <entry><literal>(1,foo) ...</literal></entry>
8914        </row>
8915        <row>
8916         <entry>
8917          <indexterm>
8918           <primary>ts_token_type</primary>
8919          </indexterm>
8920          <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>
8921         </entry>
8922         <entry><type>setof record</type></entry>
8923         <entry>get token types defined by parser</entry>
8924         <entry><literal>ts_token_type('default')</literal></entry>
8925         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8926        </row>
8927        <row>
8928         <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>
8929         <entry><type>setof record</type></entry>
8930         <entry>get token types defined by parser</entry>
8931         <entry><literal>ts_token_type(3722)</literal></entry>
8932         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8933        </row>
8934        <row>
8935         <entry>
8936          <indexterm>
8937           <primary>ts_stat</primary>
8938          </indexterm>
8939          <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>
8940         </entry>
8941         <entry><type>setof record</type></entry>
8942         <entry>get statistics of a <type>tsvector</> column</entry>
8943         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
8944         <entry><literal>(foo,10,15) ...</literal></entry>
8945        </row>
8946       </tbody>
8947      </tgroup>
8948     </table>
8949
8950  </sect1>
8951
8952
8953  <sect1 id="functions-xml">
8954   <title>XML Functions</title>
8955
8956   <para>
8957    The functions and function-like expressions described in this
8958    section operate on values of type <type>xml</type>.  Check <xref
8959    linkend="datatype-xml"> for information about the <type>xml</type>
8960    type.  The function-like expressions <function>xmlparse</function>
8961    and <function>xmlserialize</function> for converting to and from
8962    type <type>xml</type> are not repeated here.  Use of most of these
8963    functions requires the installation to have been built
8964    with <command>configure --with-libxml</>.
8965   </para>
8966
8967   <sect2 id="functions-producing-xml">
8968    <title>Producing XML Content</title>
8969
8970    <para>
8971     A set of functions and function-like expressions are available for
8972     producing XML content from SQL data.  As such, they are
8973     particularly suitable for formatting query results into XML
8974     documents for processing in client applications.
8975    </para>
8976
8977    <sect3>
8978     <title><literal>xmlcomment</literal></title>
8979
8980     <indexterm>
8981      <primary>xmlcomment</primary>
8982     </indexterm>
8983
8984 <synopsis>
8985 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8986 </synopsis>
8987
8988     <para>
8989      The function <function>xmlcomment</function> creates an XML value
8990      containing an XML comment with the specified text as content.
8991      The text cannot contain <quote><literal>--</literal></quote> or end with a
8992      <quote><literal>-</literal></quote> so that the resulting construct is a valid
8993      XML comment.  If the argument is null, the result is null.
8994     </para>
8995
8996     <para>
8997      Example:
8998 <screen><![CDATA[
8999 SELECT xmlcomment('hello');
9000
9001   xmlcomment
9002 --------------
9003  <!--hello-->
9004 ]]></screen>
9005     </para>
9006    </sect3>
9007
9008    <sect3>
9009     <title><literal>xmlconcat</literal></title>
9010
9011     <indexterm>
9012      <primary>xmlconcat</primary>
9013     </indexterm>
9014
9015 <synopsis>
9016 <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
9017 </synopsis>
9018
9019     <para>
9020      The function <function>xmlconcat</function> concatenates a list
9021      of individual XML values to create a single value containing an
9022      XML content fragment.  Null values are omitted; the result is
9023      only null if there are no nonnull arguments.
9024     </para>
9025
9026     <para>
9027      Example:
9028 <screen><![CDATA[
9029 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
9030
9031       xmlconcat
9032 ----------------------
9033  <abc/><bar>foo</bar>
9034 ]]></screen>
9035     </para>
9036
9037     <para>
9038      XML declarations, if present, are combined as follows.  If all
9039      argument values have the same XML version declaration, that
9040      version is used in the result, else no version is used.  If all
9041      argument values have the standalone declaration value
9042      <quote>yes</quote>, then that value is used in the result.  If
9043      all argument values have a standalone declaration value and at
9044      least one is <quote>no</quote>, then that is used in the result.
9045      Else the result will have no standalone declaration.  If the
9046      result is determined to require a standalone declaration but no
9047      version declaration, a version declaration with version 1.0 will
9048      be used because XML requires an XML declaration to contain a
9049      version declaration.  Encoding declarations are ignored and
9050      removed in all cases.
9051     </para>
9052
9053     <para>
9054      Example:
9055 <screen><![CDATA[
9056 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
9057
9058              xmlconcat
9059 -----------------------------------
9060  <?xml version="1.1"?><foo/><bar/>
9061 ]]></screen>
9062     </para>
9063    </sect3>
9064
9065    <sect3>
9066     <title><literal>xmlelement</literal></title>
9067
9068    <indexterm>
9069     <primary>xmlelement</primary>
9070    </indexterm>
9071
9072 <synopsis>
9073 <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>)
9074 </synopsis>
9075
9076     <para>
9077      The <function>xmlelement</function> expression produces an XML
9078      element with the given name, attributes, and content.
9079     </para>
9080
9081     <para>
9082      Examples:
9083 <screen><![CDATA[
9084 SELECT xmlelement(name foo);
9085
9086  xmlelement
9087 ------------
9088  <foo/>
9089
9090 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
9091
9092     xmlelement
9093 ------------------
9094  <foo bar="xyz"/>
9095
9096 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
9097
9098              xmlelement
9099 -------------------------------------
9100  <foo bar="2007-01-26">content</foo>
9101 ]]></screen>
9102     </para>
9103
9104     <para>
9105      Element and attribute names that are not valid XML names are
9106      escaped by replacing the offending characters by the sequence
9107      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
9108      <replaceable>HHHH</replaceable> is the character's Unicode
9109      codepoint in hexadecimal notation.  For example:
9110 <screen><![CDATA[
9111 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
9112
9113             xmlelement
9114 ----------------------------------
9115  <foo_x0024_bar a_x0026_b="xyz"/>
9116 ]]></screen>
9117     </para>
9118
9119     <para>
9120      An explicit attribute name need not be specified if the attribute
9121      value is a column reference, in which case the column's name will
9122      be used as the attribute name by default.  In other cases, the
9123      attribute must be given an explicit name.  So this example is
9124      valid:
9125 <screen>
9126 CREATE TABLE test (a xml, b xml);
9127 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
9128 </screen>
9129      But these are not:
9130 <screen>
9131 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
9132 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
9133 </screen>
9134     </para>
9135
9136     <para>
9137      Element content, if specified, will be formatted according to
9138      its data type.  If the content is itself of type <type>xml</type>,
9139      complex XML documents can be constructed.  For example:
9140 <screen><![CDATA[
9141 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
9142                             xmlelement(name abc),
9143                             xmlcomment('test'),
9144                             xmlelement(name xyz));
9145
9146                   xmlelement
9147 ----------------------------------------------
9148  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
9149 ]]></screen>
9150
9151      Content of other types will be formatted into valid XML character
9152      data.  This means in particular that the characters &lt;, &gt;,
9153      and &amp; will be converted to entities.  Binary data (data type
9154      <type>bytea</type>) will be represented in base64 or hex
9155      encoding, depending on the setting of the configuration parameter
9156      <xref linkend="guc-xmlbinary">.  The particular behavior for
9157      individual data types is expected to evolve in order to align the
9158      SQL and PostgreSQL data types with the XML Schema specification,
9159      at which point a more precise description will appear.
9160     </para>
9161    </sect3>
9162
9163    <sect3>
9164     <title><literal>xmlforest</literal></title>
9165
9166    <indexterm>
9167     <primary>xmlforest</primary>
9168    </indexterm>
9169
9170 <synopsis>
9171 <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
9172 </synopsis>
9173
9174     <para>
9175      The <function>xmlforest</function> expression produces an XML
9176      forest (sequence) of elements using the given names and content.
9177     </para>
9178
9179     <para>
9180      Examples:
9181 <screen><![CDATA[
9182 SELECT xmlforest('abc' AS foo, 123 AS bar);
9183
9184           xmlforest
9185 ------------------------------
9186  <foo>abc</foo><bar>123</bar>
9187
9188
9189 SELECT xmlforest(table_name, column_name)
9190 FROM information_schema.columns
9191 WHERE table_schema = 'pg_catalog';
9192
9193                                          xmlforest
9194 -------------------------------------------------------------------------------------------
9195  <table_name>pg_authid</table_name><column_name>rolname</column_name>
9196  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
9197  ...
9198 ]]></screen>
9199
9200      As seen in the second example, the element name can be omitted if
9201      the content value is a column reference, in which case the column
9202      name is used by default.  Otherwise, a name must be specified.
9203     </para>
9204
9205     <para>
9206      Element names that are not valid XML names are escaped as shown
9207      for <function>xmlelement</function> above.  Similarly, content
9208      data is escaped to make valid XML content, unless it is already
9209      of type <type>xml</type>.
9210     </para>
9211
9212     <para>
9213      Note that XML forests are not valid XML documents if they consist
9214      of more than one element, so it might be useful to wrap
9215      <function>xmlforest</function> expressions in
9216      <function>xmlelement</function>.
9217     </para>
9218    </sect3>
9219
9220    <sect3>
9221     <title><literal>xmlpi</literal></title>
9222
9223    <indexterm>
9224     <primary>xmlpi</primary>
9225    </indexterm>
9226
9227 <synopsis>
9228 <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
9229 </synopsis>
9230
9231     <para>
9232      The <function>xmlpi</function> expression creates an XML
9233      processing instruction.  The content, if present, must not
9234      contain the character sequence <literal>?&gt;</literal>.
9235     </para>
9236
9237     <para>
9238      Example:
9239 <screen><![CDATA[
9240 SELECT xmlpi(name php, 'echo "hello world";');
9241
9242             xmlpi
9243 -----------------------------
9244  <?php echo "hello world";?>
9245 ]]></screen>
9246     </para>
9247    </sect3>
9248
9249    <sect3>
9250     <title><literal>xmlroot</literal></title>
9251
9252    <indexterm>
9253     <primary>xmlroot</primary>
9254    </indexterm>
9255
9256 <synopsis>
9257 <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
9258 </synopsis>
9259
9260     <para>
9261      The <function>xmlroot</function> expression alters the properties
9262      of the root node of an XML value.  If a version is specified,
9263      it replaces the value in the root node's version declaration; if a
9264      standalone setting is specified, it replaces the value in the
9265      root node's standalone declaration.
9266     </para>
9267
9268     <para>
9269 <screen><![CDATA[
9270 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
9271                version '1.0', standalone yes);
9272
9273                 xmlroot
9274 ----------------------------------------
9275  <?xml version="1.0" standalone="yes"?>
9276  <content>abc</content>
9277 ]]></screen>
9278     </para>
9279    </sect3>
9280
9281    <sect3 id="functions-xml-xmlagg">
9282     <title><literal>xmlagg</literal></title>
9283
9284     <indexterm>
9285      <primary>xmlagg</primary>
9286     </indexterm>
9287
9288 <synopsis>
9289 <function>xmlagg</function>(<replaceable>xml</replaceable>)
9290 </synopsis>
9291
9292     <para>
9293      The function <function>xmlagg</function> is, unlike the other
9294      functions described here, an aggregate function.  It concatenates the
9295      input values to the aggregate function call,
9296      much like <function>xmlconcat</function> does, except that concatenation
9297      occurs across rows rather than across expressions in a single row.
9298      See <xref linkend="functions-aggregate"> for additional information
9299      about aggregate functions.
9300     </para>
9301
9302     <para>
9303      Example:
9304 <screen><![CDATA[
9305 CREATE TABLE test (y int, x xml);
9306 INSERT INTO test VALUES (1, '<foo>abc</foo>');
9307 INSERT INTO test VALUES (2, '<bar/>');
9308 SELECT xmlagg(x) FROM test;
9309         xmlagg
9310 ----------------------
9311  <foo>abc</foo><bar/>
9312 ]]></screen>
9313     </para>
9314
9315     <para>
9316      To determine the order of the concatenation, an <literal>ORDER BY</>
9317      clause may be added to the aggregate call as described in
9318      <xref linkend="syntax-aggregates">. For example:
9319
9320 <screen><![CDATA[
9321 SELECT xmlagg(x ORDER BY y DESC) FROM test;
9322         xmlagg
9323 ----------------------
9324  <bar/><foo>abc</foo>
9325 ]]></screen>
9326     </para>
9327
9328     <para>
9329      The following non-standard approach used to be recommended
9330      in previous versions, and may still be useful in specific
9331      cases:
9332
9333 <screen><![CDATA[
9334 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
9335         xmlagg
9336 ----------------------
9337  <bar/><foo>abc</foo>
9338 ]]></screen>
9339     </para>
9340    </sect3>
9341    </sect2>
9342
9343    <sect2 id="functions-xml-predicates">
9344     <title>XML Predicates</title>
9345
9346     <para>
9347      The expressions described in this section check properties
9348      of <type>xml</type> values.
9349     </para>
9350
9351    <sect3>
9352     <title><literal>IS DOCUMENT</literal></title>
9353
9354     <indexterm>
9355      <primary>IS DOCUMENT</primary>
9356     </indexterm>
9357
9358 <synopsis>
9359 <replaceable>xml</replaceable> IS DOCUMENT
9360 </synopsis>
9361
9362     <para>
9363      The expression <literal>IS DOCUMENT</literal> returns true if the
9364      argument XML value is a proper XML document, false if it is not
9365      (that is, it is a content fragment), or null if the argument is
9366      null.  See <xref linkend="datatype-xml"> about the difference
9367      between documents and content fragments.
9368     </para>
9369    </sect3>
9370
9371    <sect3 id="xml-exists">
9372     <title><literal>XMLEXISTS</literal></title>
9373
9374     <indexterm>
9375      <primary>XMLEXISTS</primary>
9376     </indexterm>
9377
9378 <synopsis>
9379 <function>XMLEXISTS</function>(<replaceable>text</replaceable> PASSING <optional>BY REF</optional> <replaceable>xml</replaceable> <optional>BY REF</optional>)
9380 </synopsis>
9381
9382     <para>
9383      The function <function>xmlexists</function> returns true if the
9384      XPath expression in the first argument returns any nodes, and
9385      false otherwise.  (If either argument is null, the result is
9386      null.)
9387     </para>
9388
9389     <para>
9390      Example:
9391      <screen><![CDATA[
9392 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY REF '<towns><town>Toronto</town><town>Ottawa</town></towns>');
9393
9394  xmlexists
9395 ------------
9396  t
9397 (1 row)
9398 ]]></screen>
9399     </para>
9400
9401     <para>
9402      The <literal>BY REF</literal> clauses have no effect in
9403      PostgreSQL, but are allowed for SQL conformance and compatibility
9404      with other implementations.  Per SQL standard, the
9405      first <literal>BY REF</literal> is required, the second is
9406      optional.  Also note that the SQL standard specifies
9407      the <function>xmlexists</function> construct to take an XQuery
9408      expression as first argument, but PostgreSQL currently only
9409      supports XPath, which is a subset of XQuery.
9410     </para>
9411    </sect3>
9412
9413    <sect3 id="xml-is-well-formed">
9414     <title><literal>xml_is_well_formed</literal></title>
9415
9416     <indexterm>
9417      <primary>xml_is_well_formed</primary>
9418     </indexterm>
9419
9420     <indexterm>
9421      <primary>xml_is_well_formed_document</primary>
9422     </indexterm>
9423
9424     <indexterm>
9425      <primary>xml_is_well_formed_content</primary>
9426     </indexterm>
9427
9428 <synopsis>
9429 <function>xml_is_well_formed</function>(<replaceable>text</replaceable>)
9430 <function>xml_is_well_formed_document</function>(<replaceable>text</replaceable>)
9431 <function>xml_is_well_formed_content</function>(<replaceable>text</replaceable>)
9432 </synopsis>
9433
9434     <para>
9435      These functions check whether a <type>text</> string is well-formed XML,
9436      returning a Boolean result.
9437      <function>xml_is_well_formed_document</function> checks for a well-formed
9438      document, while <function>xml_is_well_formed_content</function> checks
9439      for well-formed content.  <function>xml_is_well_formed</function> does
9440      the former if the <xref linkend="guc-xmloption"> configuration
9441      parameter is set to <literal>DOCUMENT</>, or the latter if it is set to
9442      <literal>CONTENT</>.  This means that
9443      <function>xml_is_well_formed</function> is useful for seeing whether
9444      a simple cast to type <type>xml</> will succeed, whereas the other two
9445      functions are useful for seeing whether the corresponding variants of
9446      <function>XMLPARSE</> will succeed.
9447     </para>
9448
9449     <para>
9450      Examples:
9451
9452 <screen><![CDATA[
9453 SET xmloption TO DOCUMENT;
9454 SELECT xml_is_well_formed('<>');
9455  xml_is_well_formed 
9456 --------------------
9457  f
9458 (1 row)
9459
9460 SELECT xml_is_well_formed('<abc/>');
9461  xml_is_well_formed 
9462 --------------------
9463  t
9464 (1 row)
9465
9466 SET xmloption TO CONTENT;
9467 SELECT xml_is_well_formed('abc');
9468  xml_is_well_formed 
9469 --------------------
9470  t
9471 (1 row)
9472
9473 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
9474  xml_is_well_formed_document 
9475 -----------------------------
9476  t
9477 (1 row)
9478
9479 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
9480  xml_is_well_formed_document 
9481 -----------------------------
9482  f
9483 (1 row)
9484 ]]></screen>
9485
9486      The last example shows that the checks include whether
9487      namespaces are correctly matched.
9488     </para>
9489    </sect3>
9490   </sect2>
9491
9492   <sect2 id="functions-xml-processing">
9493    <title>Processing XML</title>
9494
9495    <indexterm>
9496     <primary>XPath</primary>
9497    </indexterm>
9498
9499    <para>
9500     To process values of data type <type>xml</type>, PostgreSQL offers
9501     the functions <function>xpath</function> and
9502     <function>xpath_exists</function>, which evaluate XPath 1.0
9503     expressions.
9504    </para>
9505
9506 <synopsis>
9507 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9508 </synopsis>
9509
9510    <para>
9511     The function <function>xpath</function> evaluates the XPath
9512     expression <replaceable>xpath</replaceable> (a <type>text</> value)
9513     against the XML value
9514     <replaceable>xml</replaceable>.  It returns an array of XML values
9515     corresponding to the node set produced by the XPath expression.
9516     If the XPath expression returns a scalar value rather than a node set,
9517     a single-element array is returned.
9518    </para>
9519
9520   <para>
9521     The second argument must be a well formed XML document. In particular,
9522     it must have a single root node element.
9523   </para>
9524
9525    <para>
9526     The optional third argument of the function is an array of namespace
9527     mappings.  This array should be a two-dimensional <type>text</> array with
9528     the length of the second axis being equal to 2 (i.e., it should be an
9529     array of arrays, each of which consists of exactly 2 elements).
9530     The first element of each array entry is the namespace name (alias), the
9531     second the namespace URI. It is not required that aliases provided in
9532     this array be the same as those being used in the XML document itself (in
9533     other words, both in the XML document and in the <function>xpath</function>
9534     function context, aliases are <emphasis>local</>).
9535    </para>
9536
9537    <para>
9538     Example:
9539 <screen><![CDATA[
9540 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9541              ARRAY[ARRAY['my', 'http://example.com']]);
9542
9543  xpath  
9544 --------
9545  {test}
9546 (1 row)
9547 ]]></screen>
9548    </para>
9549
9550    <para>
9551     To deal with default (anonymous) namespaces, do something like this:
9552 <screen><![CDATA[
9553 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
9554              ARRAY[ARRAY['mydefns', 'http://example.com']]);
9555
9556  xpath
9557 --------
9558  {test}
9559 (1 row)
9560 ]]></screen>
9561    </para>
9562
9563    <indexterm>
9564     <primary>xpath_exists</primary>
9565    </indexterm>
9566
9567 <synopsis>
9568 <function>xpath_exists</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9569 </synopsis>
9570
9571    <para>
9572     The function <function>xpath_exists</function> is a specialized form
9573     of the <function>xpath</function> function.  Instead of returning the
9574     individual XML values that satisfy the XPath, this function returns a
9575     Boolean indicating whether the query was satisfied or not.  This
9576     function is equivalent to the standard <literal>XMLEXISTS</> predicate,
9577     except that it also offers support for a namespace mapping argument.
9578    </para>
9579
9580    <para>
9581     Example:
9582 <screen><![CDATA[
9583 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9584                      ARRAY[ARRAY['my', 'http://example.com']]);
9585
9586  xpath_exists  
9587 --------------
9588  t
9589 (1 row)
9590 ]]></screen>
9591    </para>
9592   </sect2>
9593
9594   <sect2 id="functions-xml-mapping">
9595    <title>Mapping Tables to XML</title>
9596
9597    <indexterm zone="functions-xml-mapping">
9598     <primary>XML export</primary>
9599    </indexterm>
9600
9601    <para>
9602     The following functions map the contents of relational tables to
9603     XML values.  They can be thought of as XML export functionality:
9604 <synopsis>
9605 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9606 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
9607 cursor_to_xml(cursor refcursor, count int, nulls boolean,
9608               tableforest boolean, targetns text)
9609 </synopsis>
9610     The return type of each function is <type>xml</type>.
9611    </para>
9612
9613    <para>
9614     <function>table_to_xml</function> maps the content of the named
9615     table, passed as parameter <parameter>tbl</parameter>.  The
9616     <type>regclass</type> type accepts strings identifying tables using the
9617     usual notation, including optional schema qualifications and
9618     double quotes.  <function>query_to_xml</function> executes the
9619     query whose text is passed as parameter
9620     <parameter>query</parameter> and maps the result set.
9621     <function>cursor_to_xml</function> fetches the indicated number of
9622     rows from the cursor specified by the parameter
9623     <parameter>cursor</parameter>.  This variant is recommended if
9624     large tables have to be mapped, because the result value is built
9625     up in memory by each function.
9626    </para>
9627
9628    <para>
9629     If <parameter>tableforest</parameter> is false, then the resulting
9630     XML document looks like this:
9631 <screen><![CDATA[
9632 <tablename>
9633   <row>
9634     <columnname1>data</columnname1>
9635     <columnname2>data</columnname2>
9636   </row>
9637
9638   <row>
9639     ...
9640   </row>
9641
9642   ...
9643 </tablename>
9644 ]]></screen>
9645
9646     If <parameter>tableforest</parameter> is true, the result is an
9647     XML content fragment that looks like this:
9648 <screen><![CDATA[
9649 <tablename>
9650   <columnname1>data</columnname1>
9651   <columnname2>data</columnname2>
9652 </tablename>
9653
9654 <tablename>
9655   ...
9656 </tablename>
9657
9658 ...
9659 ]]></screen>
9660
9661     If no table name is available, that is, when mapping a query or a
9662     cursor, the string <literal>table</literal> is used in the first
9663     format, <literal>row</literal> in the second format.
9664    </para>
9665
9666    <para>
9667     The choice between these formats is up to the user.  The first
9668     format is a proper XML document, which will be important in many
9669     applications.  The second format tends to be more useful in the
9670     <function>cursor_to_xml</function> function if the result values are to be
9671     reassembled into one document later on.  The functions for
9672     producing XML content discussed above, in particular
9673     <function>xmlelement</function>, can be used to alter the results
9674     to taste.
9675    </para>
9676
9677    <para>
9678     The data values are mapped in the same way as described for the
9679     function <function>xmlelement</function> above.
9680    </para>
9681
9682    <para>
9683     The parameter <parameter>nulls</parameter> determines whether null
9684     values should be included in the output.  If true, null values in
9685     columns are represented as:
9686 <screen><![CDATA[
9687 <columnname xsi:nil="true"/>
9688 ]]></screen>
9689     where <literal>xsi</literal> is the XML namespace prefix for XML
9690     Schema Instance.  An appropriate namespace declaration will be
9691     added to the result value.  If false, columns containing null
9692     values are simply omitted from the output.
9693    </para>
9694
9695    <para>
9696     The parameter <parameter>targetns</parameter> specifies the
9697     desired XML namespace of the result.  If no particular namespace
9698     is wanted, an empty string should be passed.
9699    </para>
9700
9701    <para>
9702     The following functions return XML Schema documents describing the
9703     mappings performed by the corresponding functions above:
9704 <synopsis>
9705 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9706 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9707 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
9708 </synopsis>
9709     It is essential that the same parameters are passed in order to
9710     obtain matching XML data mappings and XML Schema documents.
9711    </para>
9712
9713    <para>
9714     The following functions produce XML data mappings and the
9715     corresponding XML Schema in one document (or forest), linked
9716     together.  They can be useful where self-contained and
9717     self-describing results are wanted:
9718 <synopsis>
9719 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9720 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9721 </synopsis>
9722    </para>
9723
9724    <para>
9725     In addition, the following functions are available to produce
9726     analogous mappings of entire schemas or the entire current
9727     database:
9728 <synopsis>
9729 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
9730 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9731 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9732
9733 database_to_xml(nulls boolean, tableforest boolean, targetns text)
9734 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
9735 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
9736 </synopsis>
9737
9738     Note that these potentially produce a lot of data, which needs to
9739     be built up in memory.  When requesting content mappings of large
9740     schemas or databases, it might be worthwhile to consider mapping the
9741     tables separately instead, possibly even through a cursor.
9742    </para>
9743
9744    <para>
9745     The result of a schema content mapping looks like this:
9746
9747 <screen><![CDATA[
9748 <schemaname>
9749
9750 table1-mapping
9751
9752 table2-mapping
9753
9754 ...
9755
9756 </schemaname>]]></screen>
9757
9758     where the format of a table mapping depends on the
9759     <parameter>tableforest</parameter> parameter as explained above.
9760    </para>
9761
9762    <para>
9763     The result of a database content mapping looks like this:
9764
9765 <screen><![CDATA[
9766 <dbname>
9767
9768 <schema1name>
9769   ...
9770 </schema1name>
9771
9772 <schema2name>
9773   ...
9774 </schema2name>
9775
9776 ...
9777
9778 </dbname>]]></screen>
9779
9780     where the schema mapping is as above.
9781    </para>
9782
9783    <para>
9784     As an example of using the output produced by these functions,
9785     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
9786     converts the output of
9787     <function>table_to_xml_and_xmlschema</function> to an HTML
9788     document containing a tabular rendition of the table data.  In a
9789     similar manner, the results from these functions can be
9790     converted into other XML-based formats.
9791    </para>
9792
9793    <figure id="xslt-xml-html">
9794     <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
9795 <programlisting><![CDATA[
9796 <?xml version="1.0"?>
9797 <xsl:stylesheet version="1.0"
9798     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
9799     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
9800     xmlns="http://www.w3.org/1999/xhtml"
9801 >
9802
9803   <xsl:output method="xml"
9804       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
9805       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
9806       indent="yes"/>
9807
9808   <xsl:template match="/*">
9809     <xsl:variable name="schema" select="//xsd:schema"/>
9810     <xsl:variable name="tabletypename"
9811                   select="$schema/xsd:element[@name=name(current())]/@type"/>
9812     <xsl:variable name="rowtypename"
9813                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
9814
9815     <html>
9816       <head>
9817         <title><xsl:value-of select="name(current())"/></title>
9818       </head>
9819       <body>
9820         <table>
9821           <tr>
9822             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
9823               <th><xsl:value-of select="."/></th>
9824             </xsl:for-each>
9825           </tr>
9826
9827           <xsl:for-each select="row">
9828             <tr>
9829               <xsl:for-each select="*">
9830                 <td><xsl:value-of select="."/></td>
9831               </xsl:for-each>
9832             </tr>
9833           </xsl:for-each>
9834         </table>
9835       </body>
9836     </html>
9837   </xsl:template>
9838
9839 </xsl:stylesheet>
9840 ]]></programlisting>
9841    </figure>
9842   </sect2>
9843  </sect1>
9844
9845  <sect1 id="functions-json">
9846   <title>JSON Functions and Operators</title>
9847
9848   <indexterm zone="functions-json">
9849     <primary>JSON</primary>
9850     <secondary>Functions and operators</secondary>
9851   </indexterm>
9852
9853    <para>
9854    <xref linkend="functions-json-op-table"> shows the operators that are
9855    available for use with JSON (see <xref linkend="datatype-json">) data.
9856   </para>
9857
9858   <table id="functions-json-op-table">
9859      <title>JSON Operators</title>
9860      <tgroup cols="4">
9861       <thead>
9862        <row>
9863         <entry>Operator</entry>
9864         <entry>Right Operand Type</entry>
9865         <entry>Description</entry>
9866         <entry>Example</entry>
9867        </row>
9868       </thead>
9869       <tbody>
9870        <row>
9871         <entry><literal>-&gt;</literal></entry>
9872         <entry>int</entry>
9873         <entry>Get JSON array element</entry>
9874         <entry><literal>'[1,2,3]'::json-&gt;2</literal></entry>
9875        </row>
9876        <row>
9877         <entry><literal>-&gt;</literal></entry>
9878         <entry>text</entry>
9879         <entry>Get JSON object field</entry>
9880         <entry><literal>'{"a":1,"b":2}'::json-&gt;'b'</literal></entry>
9881        </row>
9882         <row>
9883         <entry><literal>-&gt;&gt;</literal></entry>
9884         <entry>int</entry>
9885         <entry>Get JSON array element as text</entry>
9886         <entry><literal>'[1,2,3]'::json-&gt;&gt;2</literal></entry>
9887        </row>
9888        <row>
9889         <entry><literal>-&gt;&gt;</literal></entry>
9890         <entry>text</entry>
9891         <entry>Get JSON object field as text</entry>
9892         <entry><literal>'{"a":1,"b":2}'::json-&gt;&gt;'b'</literal></entry>
9893        </row>
9894        <row>
9895         <entry><literal>#&gt;</literal></entry>
9896         <entry>array of text</entry>
9897         <entry>Get JSON object at specified path</entry>
9898         <entry><literal>'{"a":[1,2,3],"b":[4,5,6]}'::json#&gt;'{a,2}'</literal></entry>
9899        </row>
9900        <row>
9901         <entry><literal>#&gt;&gt;</literal></entry>
9902         <entry>array of text</entry>
9903         <entry>Get JSON object at specified path as text</entry>
9904         <entry><literal>'{"a":[1,2,3],"b":[4,5,6]}'::json#&gt;&gt;'{a,2}'</literal></entry>
9905        </row>
9906       </tbody>
9907      </tgroup>
9908    </table>
9909
9910   <para>
9911    <xref linkend="functions-json-table"> shows the functions that are available
9912    for creating and manipulating JSON (see <xref linkend="datatype-json">) data.
9913   </para>
9914
9915   <table id="functions-json-table">
9916     <title>JSON Support Functions</title>
9917     <tgroup cols="5">
9918      <thead>
9919       <row>
9920        <entry>Function</entry>
9921        <entry>Return Type</entry>
9922        <entry>Description</entry>
9923        <entry>Example</entry>
9924        <entry>Example Result</entry>
9925       </row>
9926      </thead>
9927      <tbody>
9928       <row>
9929        <entry>
9930          <indexterm>
9931           <primary>array_to_json</primary>
9932          </indexterm>
9933          <literal>array_to_json(anyarray [, pretty_bool])</literal>
9934        </entry>
9935        <entry><type>json</type></entry>
9936        <entry>
9937          Returns the array as JSON. A PostgreSQL multidimensional array
9938          becomes a JSON array of arrays. Line feeds will be added between
9939          dimension 1 elements if <parameter>pretty_bool</parameter> is true.
9940        </entry>
9941        <entry><literal>array_to_json('{{1,5},{99,100}}'::int[])</literal></entry>
9942        <entry><literal>[[1,5],[99,100]]</literal></entry>
9943       </row>
9944       <row>
9945        <entry>
9946          <indexterm>
9947           <primary>row_to_json</primary>
9948          </indexterm>
9949          <literal>row_to_json(record [, pretty_bool])</literal>
9950        </entry>
9951        <entry><type>json</type></entry>
9952        <entry>
9953          Returns the row as JSON. Line feeds will be added between level
9954          1 elements if <parameter>pretty_bool</parameter> is true.
9955        </entry>
9956        <entry><literal>row_to_json(row(1,'foo'))</literal></entry>
9957        <entry><literal>{"f1":1,"f2":"foo"}</literal></entry>
9958       </row>
9959       <row>
9960        <entry>
9961          <indexterm>
9962           <primary>to_json</primary>
9963          </indexterm>
9964          <literal>to_json(anyelement)</literal>
9965        </entry>
9966        <entry><type>json</type></entry>
9967        <entry>
9968          Returns the value as JSON. If the data type is not built in, and there
9969          is a cast from the type to <type>json</type>, the cast function will be used to
9970          perform the conversion. Otherwise, for any value other than a number,
9971          a Boolean, or a null value, the text representation will be used, escaped and
9972          quoted so that it is legal JSON.
9973        </entry>
9974        <entry><literal>to_json('Fred said "Hi."'::text)</literal></entry>
9975        <entry><literal>"Fred said \"Hi.\""</literal></entry>
9976       </row>
9977       <row>
9978        <entry>
9979          <indexterm>
9980           <primary>json_array_length</primary>
9981          </indexterm>
9982          <literal>json_array_length(json)</literal>
9983        </entry>
9984        <entry><type>int</type></entry>
9985        <entry>
9986          Returns the number of elements in the outermost JSON array.
9987        </entry>
9988        <entry><literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal></entry>
9989        <entry><literal>5</literal></entry>
9990       </row>
9991       <row>
9992        <entry>
9993          <indexterm>
9994           <primary>json_each</primary>
9995          </indexterm>
9996          <literal>json_each(json)</literal>
9997        </entry>
9998        <entry><type>SETOF key text, value json</type></entry>
9999        <entry>
10000          Expands the outermost JSON object into a set of key/value pairs.
10001        </entry>
10002        <entry><literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal></entry>
10003        <entry>
10004 <programlisting>
10005  key | value
10006 -----+-------
10007  a   | "foo"
10008  b   | "bar"
10009  </programlisting>
10010        </entry>
10011       </row>
10012       <row>
10013        <entry>
10014          <indexterm>
10015           <primary>json_each_text</primary>
10016          </indexterm>
10017          <literal>json_each_text(from_json json)</literal>
10018        </entry>
10019        <entry><type>SETOF key text, value text</type></entry>
10020        <entry>
10021          Expands the outermost JSON object into a set of key/value pairs. The
10022          returned value will be of type text.
10023        </entry>
10024        <entry><literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal></entry>
10025        <entry>
10026 <programlisting>
10027  key | value
10028 -----+-------
10029  a   | foo
10030  b   | bar
10031  </programlisting>
10032        </entry>
10033       </row>
10034       <row>
10035        <entry>
10036          <indexterm>
10037           <primary>json_extract_path</primary>
10038          </indexterm>
10039          <literal>json_extract_path(from_json json, VARIADIC path_elems text[])</literal>
10040        </entry>
10041        <entry><type>json</type></entry>
10042        <entry>
10043          Returns JSON object pointed to by <parameter>path_elems</parameter>.
10044        </entry>
10045        <entry><literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</literal></entry>
10046        <entry><literal>{"f5":99,"f6":"foo"}</literal></entry>
10047       </row>
10048       <row>
10049        <entry>
10050          <indexterm>
10051           <primary>json_extract_path_text</primary>
10052          </indexterm>
10053          <literal>json_extract_path_text(from_json json, VARIADIC path_elems text[])</literal>
10054        </entry>
10055        <entry><type>text</type></entry>
10056        <entry>
10057          Returns JSON object pointed to by <parameter>path_elems</parameter>.
10058        </entry>
10059        <entry><literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</literal></entry>
10060        <entry><literal>foo</literal></entry>
10061       </row>
10062       <row>
10063        <entry>
10064          <indexterm>
10065           <primary>json_object_keys</primary>
10066          </indexterm>
10067          <literal>json_object_keys(json)</literal>
10068        </entry>
10069        <entry><type>SETOF text</type></entry>
10070        <entry>
10071           Returns set of keys in the JSON object.  Only the <quote>outer</quote> object will be displayed.
10072        </entry>
10073        <entry><literal>json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal></entry>
10074        <entry>
10075 <programlisting>
10076  json_object_keys
10077 ------------------
10078  f1
10079  f2
10080 </programlisting>
10081        </entry>
10082       </row>
10083       <row>
10084        <entry>
10085          <indexterm>
10086           <primary>json_populate_record</primary>
10087          </indexterm>
10088          <literal>json_populate_record(base anyelement, from_json json, [, use_json_as_text bool=false]</literal>
10089        </entry>
10090        <entry><type>anyelement</type></entry>
10091        <entry>
10092          Expands the object in <replaceable>from_json</replaceable> to a row whose columns match
10093          the record type defined by base. Conversion will be best
10094          effort; columns in base with no corresponding key in <replaceable>from_json</replaceable>
10095          will be left null.  A column may only be specified once.
10096        </entry>
10097        <entry><literal>select * from json_populate_record(null::x, '{"a":1,"b":2}')</literal></entry>
10098        <entry>
10099 <programlisting>
10100  a | b
10101 ---+---
10102  1 | 2
10103 </programlisting>
10104        </entry>
10105       </row>
10106       <row>
10107        <entry>
10108          <indexterm>
10109           <primary>json_populate_recordset</primary>
10110          </indexterm>
10111          <literal>json_populate_recordset(base anyelement, from_json json, [, use_json_as_text bool=false]</literal>
10112        </entry>
10113        <entry><type>SETOF anyelement</type></entry>
10114        <entry>
10115          Expands the outermost set of objects in <replaceable>from_json</replaceable> to a set
10116          whose columns match the record type defined by base.
10117          Conversion will be best effort; columns in base with no
10118          corresponding key in <replaceable>from_json</replaceable> will be left null.  A column
10119          may only be specified once.
10120        </entry>
10121        <entry><literal>select * from json_populate_recordset(null::x, '[{"a":1,"b":2},{"a":3,"b":4}]')</literal></entry>
10122        <entry>
10123 <programlisting>
10124  a | b
10125 ---+---
10126  1 | 2
10127  3 | 4
10128  </programlisting>
10129        </entry>
10130       </row>
10131       <row>
10132        <entry>
10133          <indexterm>
10134           <primary>json_array_elements</primary>
10135          </indexterm>
10136          <literal>json_array_elements(json)</literal>
10137        </entry>
10138        <entry><type>SETOF json</type></entry>
10139        <entry>
10140          Expands a JSON array to a set of JSON elements.
10141        </entry>
10142        <entry><literal>json_array_elements('[1,true, [2,false]]')</literal></entry>
10143        <entry>
10144 <programlisting>
10145    value
10146 -----------
10147  1
10148  true
10149  [2,false]
10150 </programlisting>
10151        </entry>
10152       </row>
10153      </tbody>
10154     </tgroup>
10155    </table>
10156
10157   <note>
10158     <para>
10159       The <type>json</type> functions and operators can impose stricter validity requirements
10160       than the type's input functions. In particular, they check much more closely that any use
10161       of Unicode surrogate pairs to designate characters outside the Unicode Basic Multilingual
10162       Plane is correct.
10163     </para>
10164   </note>
10165
10166   <note>
10167     <para>
10168       Many of these functions and operators will convert Unicode escapes
10169       in the JSON text to the appropriate UTF8 character when the database encoding is UTF8. In
10170       other encodings the escape sequence must be for an ASCII character, and any other code point
10171       in a Unicode escape sequence will result in an error.
10172       In general, it is best to avoid mixing Unicode escapes in JSON with a non-UTF8 database
10173       encoding, if possible.
10174     </para>
10175   </note>
10176
10177   <note>
10178     <para>
10179       The <xref linkend="hstore"> extension has a cast from <type>hstore</type> to
10180       <type>json</type>, so that converted <type>hstore</type> values are represented as JSON objects,
10181       not as string values.
10182     </para>
10183   </note>
10184
10185   <para>
10186     See also <xref linkend="functions-aggregate"> about the aggregate
10187     function <function>json_agg</function> which aggregates record
10188     values as JSON efficiently.
10189   </para>
10190  </sect1>
10191
10192  <sect1 id="functions-sequence">
10193   <title>Sequence Manipulation Functions</title>
10194
10195   <indexterm>
10196    <primary>sequence</primary>
10197   </indexterm>
10198   <indexterm>
10199    <primary>nextval</primary>
10200   </indexterm>
10201   <indexterm>
10202    <primary>currval</primary>
10203   </indexterm>
10204   <indexterm>
10205    <primary>lastval</primary>
10206   </indexterm>
10207   <indexterm>
10208    <primary>setval</primary>
10209   </indexterm>
10210
10211   <para>
10212    This section describes functions for operating on <firstterm>sequence
10213    objects</firstterm>, also called sequence generators or just sequences.
10214    Sequence objects are special single-row tables created with <xref
10215    linkend="sql-createsequence">.
10216    Sequence objects are commonly used to generate unique identifiers
10217    for rows of a table.  The sequence functions, listed in <xref
10218    linkend="functions-sequence-table">, provide simple, multiuser-safe
10219    methods for obtaining successive sequence values from sequence
10220    objects.
10221   </para>
10222
10223    <table id="functions-sequence-table">
10224     <title>Sequence Functions</title>
10225     <tgroup cols="3">
10226      <thead>
10227       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
10228      </thead>
10229
10230      <tbody>
10231       <row>
10232         <entry><literal><function>currval(<type>regclass</type>)</function></literal></entry>
10233         <entry><type>bigint</type></entry>
10234         <entry>Return value most recently obtained with
10235         <function>nextval</function> for specified sequence</entry>
10236       </row>
10237       <row>
10238         <entry><literal><function>lastval()</function></literal></entry>
10239         <entry><type>bigint</type></entry>
10240         <entry>Return value most recently obtained with
10241         <function>nextval</function> for any sequence</entry>
10242       </row>
10243       <row>
10244         <entry><literal><function>nextval(<type>regclass</type>)</function></literal></entry>
10245         <entry><type>bigint</type></entry>
10246         <entry>Advance sequence and return new value</entry>
10247       </row>
10248       <row>
10249         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>)</function></literal></entry>
10250         <entry><type>bigint</type></entry>
10251         <entry>Set sequence's current value</entry>
10252       </row>
10253       <row>
10254         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</function></literal></entry>
10255         <entry><type>bigint</type></entry>
10256         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
10257       </row>
10258      </tbody>
10259     </tgroup>
10260    </table>
10261
10262   <para>
10263    The sequence to be operated on by a sequence function is specified by
10264    a <type>regclass</> argument, which is simply the OID of the sequence in the
10265    <structname>pg_class</> system catalog.  You do not have to look up the
10266    OID by hand, however, since the <type>regclass</> data type's input
10267    converter will do the work for you.  Just write the sequence name enclosed
10268    in single quotes so that it looks like a literal constant.  For
10269    compatibility with the handling of ordinary
10270    <acronym>SQL</acronym> names, the string will be converted to lower case
10271    unless it contains double quotes around the sequence name.  Thus:
10272 <programlisting>
10273 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
10274 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
10275 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
10276 </programlisting>
10277    The sequence name can be schema-qualified if necessary:
10278 <programlisting>
10279 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
10280 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
10281 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
10282 </programlisting>
10283    See <xref linkend="datatype-oid"> for more information about
10284    <type>regclass</>.
10285   </para>
10286
10287   <note>
10288    <para>
10289     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
10290     sequence functions were of type <type>text</>, not <type>regclass</>, and
10291     the above-described conversion from a text string to an OID value would
10292     happen at run time during each call.  For backward compatibility, this
10293     facility still exists, but internally it is now handled as an implicit
10294     coercion from <type>text</> to <type>regclass</> before the function is
10295     invoked.
10296    </para>
10297
10298    <para>
10299     When you write the argument of a sequence function as an unadorned
10300     literal string, it becomes a constant of type <type>regclass</>.
10301     Since this is really just an OID, it will track the originally
10302     identified sequence despite later renaming, schema reassignment,
10303     etc.  This <quote>early binding</> behavior is usually desirable for
10304     sequence references in column defaults and views.  But sometimes you might
10305     want <quote>late binding</> where the sequence reference is resolved
10306     at run time.  To get late-binding behavior, force the constant to be
10307     stored as a <type>text</> constant instead of <type>regclass</>:
10308 <programlisting>
10309 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
10310 </programlisting>
10311     Note that late binding was the only behavior supported in
10312     <productname>PostgreSQL</productname> releases before 8.1, so you
10313     might need to do this to preserve the semantics of old applications.
10314    </para>
10315
10316    <para>
10317     Of course, the argument of a sequence function can be an expression
10318     as well as a constant.  If it is a text expression then the implicit
10319     coercion will result in a run-time lookup.
10320    </para>
10321   </note>
10322
10323   <para>
10324    The available sequence functions are:
10325
10326     <variablelist>
10327      <varlistentry>
10328       <term><function>nextval</function></term>
10329       <listitem>
10330        <para>
10331         Advance the sequence object to its next value and return that
10332         value.  This is done atomically: even if multiple sessions
10333         execute <function>nextval</function> concurrently, each will safely receive
10334         a distinct sequence value.
10335        </para>
10336
10337        <para>
10338         If a sequence object has been created with default parameters,
10339         successive <function>nextval</function> calls will return successive
10340         values beginning with 1.  Other behaviors can be obtained by using
10341         special parameters in the <xref linkend="sql-createsequence"> command;
10342         see its command reference page for more information.
10343        </para>
10344
10345        <important>
10346         <para>
10347          To avoid blocking concurrent transactions that obtain numbers from the
10348          same sequence, a <function>nextval</function> operation is never
10349          rolled back; that is, once a value has been fetched it is considered
10350          used, even if the transaction that did the
10351          <function>nextval</function> later aborts.  This means that aborted
10352          transactions might leave unused <quote>holes</quote> in the sequence
10353          of assigned values.
10354         </para>
10355        </important>
10356
10357       </listitem>
10358      </varlistentry>
10359
10360      <varlistentry>
10361       <term><function>currval</function></term>
10362       <listitem>
10363        <para>
10364         Return the value most recently obtained by <function>nextval</function>
10365         for this sequence in the current session.  (An error is
10366         reported if <function>nextval</function> has never been called for this
10367         sequence in this session.)  Because this is returning
10368         a session-local value, it gives a predictable answer whether or not
10369         other sessions have executed <function>nextval</function> since the
10370         current session did.
10371        </para>
10372       </listitem>
10373      </varlistentry>
10374
10375      <varlistentry>
10376       <term><function>lastval</function></term>
10377       <listitem>
10378        <para>
10379         Return the value most recently returned by
10380         <function>nextval</> in the current session. This function is
10381         identical to <function>currval</function>, except that instead
10382         of taking the sequence name as an argument it fetches the
10383         value of the last sequence used by <function>nextval</function>
10384         in the current session. It is an error to call
10385         <function>lastval</function> if <function>nextval</function>
10386         has not yet been called in the current session.
10387        </para>
10388       </listitem>
10389      </varlistentry>
10390
10391      <varlistentry>
10392       <term><function>setval</function></term>
10393       <listitem>
10394        <para>
10395         Reset the sequence object's counter value.  The two-parameter
10396         form sets the sequence's <literal>last_value</literal> field to the
10397         specified value and sets its <literal>is_called</literal> field to
10398         <literal>true</literal>, meaning that the next
10399         <function>nextval</function> will advance the sequence before
10400         returning a value.  The value reported by <function>currval</> is
10401         also set to the specified value.  In the three-parameter form,
10402         <literal>is_called</literal> can be set to either <literal>true</literal>
10403         or <literal>false</literal>.  <literal>true</> has the same effect as
10404         the two-parameter form. If it is set to <literal>false</literal>, the
10405         next <function>nextval</function> will return exactly the specified
10406         value, and sequence advancement commences with the following
10407         <function>nextval</function>.  Furthermore, the value reported by
10408         <function>currval</> is not changed in this case (this is a change
10409         from pre-8.3 behavior).  For example,
10410
10411 <screen>
10412 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
10413 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
10414 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
10415 </screen>
10416
10417         The result returned by <function>setval</function> is just the value of its
10418         second argument.
10419        </para>
10420        <important>
10421         <para>
10422          Because sequences are non-transactional, changes made by
10423          <function>setval</function> are not undone if the transaction rolls
10424          back.
10425         </para>
10426        </important>
10427       </listitem>
10428      </varlistentry>
10429     </variablelist>
10430   </para>
10431
10432  </sect1>
10433
10434
10435  <sect1 id="functions-conditional">
10436   <title>Conditional Expressions</title>
10437
10438   <indexterm>
10439    <primary>CASE</primary>
10440   </indexterm>
10441
10442   <indexterm>
10443    <primary>conditional expression</primary>
10444   </indexterm>
10445
10446   <para>
10447    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
10448    available in <productname>PostgreSQL</productname>.
10449   </para>
10450
10451   <tip>
10452    <para>
10453     If your needs go beyond the capabilities of these conditional
10454     expressions, you might want to consider writing a stored procedure
10455     in a more expressive programming language.
10456    </para>
10457   </tip>
10458
10459   <sect2 id="functions-case">
10460    <title><literal>CASE</></title>
10461
10462   <para>
10463    The <acronym>SQL</acronym> <token>CASE</token> expression is a
10464    generic conditional expression, similar to if/else statements in
10465    other programming languages:
10466
10467 <synopsis>
10468 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
10469      <optional>WHEN ...</optional>
10470      <optional>ELSE <replaceable>result</replaceable></optional>
10471 END
10472 </synopsis>
10473
10474    <token>CASE</token> clauses can be used wherever
10475    an expression is valid.  Each <replaceable>condition</replaceable> is an
10476    expression that returns a <type>boolean</type> result.  If the condition's
10477    result is true, the value of the <token>CASE</token> expression is the
10478    <replaceable>result</replaceable> that follows the condition, and the
10479    remainder of the <token>CASE</token> expression is not processed.  If the
10480    condition's result is not true, any subsequent <token>WHEN</token> clauses
10481    are examined in the same manner.  If no <token>WHEN</token>
10482    <replaceable>condition</replaceable> yields true, the value of the
10483    <token>CASE</> expression is the <replaceable>result</replaceable> of the
10484    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
10485    omitted and no condition is true, the result is null.
10486   </para>
10487
10488    <para>
10489     An example:
10490 <screen>
10491 SELECT * FROM test;
10492
10493  a
10494 ---
10495  1
10496  2
10497  3
10498
10499
10500 SELECT a,
10501        CASE WHEN a=1 THEN 'one'
10502             WHEN a=2 THEN 'two'
10503             ELSE 'other'
10504        END
10505     FROM test;
10506
10507  a | case
10508 ---+-------
10509  1 | one
10510  2 | two
10511  3 | other
10512 </screen>
10513    </para>
10514
10515   <para>
10516    The data types of all the <replaceable>result</replaceable>
10517    expressions must be convertible to a single output type.
10518    See <xref linkend="typeconv-union-case"> for more details.
10519   </para>
10520
10521   <para>
10522    There is a <quote>simple</> form of <token>CASE</token> expression
10523    that is a variant of the general form above:
10524
10525 <synopsis>
10526 CASE <replaceable>expression</replaceable>
10527     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
10528     <optional>WHEN ...</optional>
10529     <optional>ELSE <replaceable>result</replaceable></optional>
10530 END
10531 </synopsis>
10532
10533    The first
10534    <replaceable>expression</replaceable> is computed, then compared to
10535    each of the <replaceable>value</replaceable> expressions in the
10536    <token>WHEN</token> clauses until one is found that is equal to it.  If
10537    no match is found, the <replaceable>result</replaceable> of the
10538    <token>ELSE</token> clause (or a null value) is returned.  This is similar
10539    to the <function>switch</function> statement in C.
10540   </para>
10541
10542    <para>
10543     The example above can be written using the simple
10544     <token>CASE</token> syntax:
10545 <screen>
10546 SELECT a,
10547        CASE a WHEN 1 THEN 'one'
10548               WHEN 2 THEN 'two'
10549               ELSE 'other'
10550        END
10551     FROM test;
10552
10553  a | case
10554 ---+-------
10555  1 | one
10556  2 | two
10557  3 | other
10558 </screen>
10559    </para>
10560
10561    <para>
10562     A <token>CASE</token> expression does not evaluate any subexpressions
10563     that are not needed to determine the result.  For example, this is a
10564     possible way of avoiding a division-by-zero failure:
10565 <programlisting>
10566 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
10567 </programlisting>
10568    </para>
10569
10570    <note>
10571     <para>
10572      As described in <xref linkend="xfunc-volatility">, functions and
10573      operators marked <literal>IMMUTABLE</literal> can be evaluated when
10574      the query is planned rather than when it is executed.  This means
10575      that constant parts of a subexpression that is not evaluated during
10576      query execution might still be evaluated during query planning.
10577     </para>
10578    </note>
10579   </sect2>
10580
10581   <sect2 id="functions-coalesce-nvl-ifnull">
10582    <title><literal>COALESCE</></title>
10583
10584   <indexterm>
10585    <primary>COALESCE</primary>
10586   </indexterm>
10587
10588   <indexterm>
10589    <primary>NVL</primary>
10590   </indexterm>
10591
10592   <indexterm>
10593    <primary>IFNULL</primary>
10594   </indexterm>
10595
10596 <synopsis>
10597 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10598 </synopsis>
10599
10600   <para>
10601    The <function>COALESCE</function> function returns the first of its
10602    arguments that is not null.  Null is returned only if all arguments
10603    are null.  It is often used to substitute a default value for
10604    null values when data is retrieved for display, for example:
10605 <programlisting>
10606 SELECT COALESCE(description, short_description, '(none)') ...
10607 </programlisting>
10608    This returns <varname>description</> if it is not null, otherwise
10609    <varname>short_description</> if it is not null, otherwise <literal>(none)</>.
10610   </para>
10611
10612    <para>
10613     Like a <token>CASE</token> expression, <function>COALESCE</function> only
10614     evaluates the arguments that are needed to determine the result;
10615     that is, arguments to the right of the first non-null argument are
10616     not evaluated.  This SQL-standard function provides capabilities similar
10617     to <function>NVL</> and <function>IFNULL</>, which are used in some other
10618     database systems.
10619    </para>
10620   </sect2>
10621
10622   <sect2 id="functions-nullif">
10623    <title><literal>NULLIF</></title>
10624
10625   <indexterm>
10626    <primary>NULLIF</primary>
10627   </indexterm>
10628
10629 <synopsis>
10630 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
10631 </synopsis>
10632
10633   <para>
10634    The <function>NULLIF</function> function returns a null value if
10635    <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
10636    otherwise it returns <replaceable>value1</replaceable>.
10637    This can be used to perform the inverse operation of the
10638    <function>COALESCE</function> example given above:
10639 <programlisting>
10640 SELECT NULLIF(value, '(none)') ...
10641 </programlisting>
10642   </para>
10643   <para>
10644    In this example, if <literal>value</literal> is <literal>(none)</>,
10645    null is returned, otherwise the value of <literal>value</literal>
10646    is returned.
10647   </para>
10648
10649   </sect2>
10650
10651   <sect2 id="functions-greatest-least">
10652    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
10653
10654   <indexterm>
10655    <primary>GREATEST</primary>
10656   </indexterm>
10657   <indexterm>
10658    <primary>LEAST</primary>
10659   </indexterm>
10660
10661 <synopsis>
10662 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10663 </synopsis>
10664 <synopsis>
10665 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10666 </synopsis>
10667
10668    <para>
10669     The <function>GREATEST</> and <function>LEAST</> functions select the
10670     largest or smallest value from a list of any number of expressions.
10671     The expressions must all be convertible to a common data type, which
10672     will be the type of the result
10673     (see <xref linkend="typeconv-union-case"> for details).  NULL values
10674     in the list are ignored.  The result will be NULL only if all the
10675     expressions evaluate to NULL.
10676    </para>
10677
10678    <para>
10679     Note that <function>GREATEST</> and <function>LEAST</> are not in
10680     the SQL standard, but are a common extension.  Some other databases
10681     make them return NULL if any argument is NULL, rather than only when
10682     all are NULL.
10683    </para>
10684   </sect2>
10685  </sect1>
10686
10687  <sect1 id="functions-array">
10688   <title>Array Functions and Operators</title>
10689
10690   <para>
10691    <xref linkend="array-operators-table"> shows the operators
10692    available for array types.
10693   </para>
10694
10695     <table id="array-operators-table">
10696      <title>Array Operators</title>
10697      <tgroup cols="4">
10698       <thead>
10699        <row>
10700         <entry>Operator</entry>
10701         <entry>Description</entry>
10702         <entry>Example</entry>
10703         <entry>Result</entry>
10704        </row>
10705       </thead>
10706       <tbody>
10707        <row>
10708         <entry> <literal>=</literal> </entry>
10709         <entry>equal</entry>
10710         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
10711         <entry><literal>t</literal></entry>
10712        </row>
10713
10714        <row>
10715         <entry> <literal>&lt;&gt;</literal> </entry>
10716         <entry>not equal</entry>
10717         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
10718         <entry><literal>t</literal></entry>
10719        </row>
10720
10721        <row>
10722         <entry> <literal>&lt;</literal> </entry>
10723         <entry>less than</entry>
10724         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
10725         <entry><literal>t</literal></entry>
10726        </row>
10727
10728        <row>
10729         <entry> <literal>&gt;</literal> </entry>
10730         <entry>greater than</entry>
10731         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
10732         <entry><literal>t</literal></entry>
10733        </row>
10734
10735        <row>
10736         <entry> <literal>&lt;=</literal> </entry>
10737         <entry>less than or equal</entry>
10738         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
10739         <entry><literal>t</literal></entry>
10740        </row>
10741
10742        <row>
10743         <entry> <literal>&gt;=</literal> </entry>
10744         <entry>greater than or equal</entry>
10745         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
10746         <entry><literal>t</literal></entry>
10747        </row>
10748
10749        <row>
10750         <entry> <literal>@&gt;</literal> </entry>
10751         <entry>contains</entry>
10752         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
10753         <entry><literal>t</literal></entry>
10754        </row>
10755
10756        <row>
10757         <entry> <literal>&lt;@</literal> </entry>
10758         <entry>is contained by</entry>
10759         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
10760         <entry><literal>t</literal></entry>
10761        </row>
10762
10763        <row>
10764         <entry> <literal>&amp;&amp;</literal> </entry>
10765         <entry>overlap (have elements in common)</entry>
10766         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
10767         <entry><literal>t</literal></entry>
10768        </row>
10769
10770        <row>
10771         <entry> <literal>||</literal> </entry>
10772         <entry>array-to-array concatenation</entry>
10773         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
10774         <entry><literal>{1,2,3,4,5,6}</literal></entry>
10775        </row>
10776
10777        <row>
10778         <entry> <literal>||</literal> </entry>
10779         <entry>array-to-array concatenation</entry>
10780         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
10781         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
10782        </row>
10783
10784        <row>
10785         <entry> <literal>||</literal> </entry>
10786         <entry>element-to-array concatenation</entry>
10787         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
10788         <entry><literal>{3,4,5,6}</literal></entry>
10789        </row>
10790
10791        <row>
10792         <entry> <literal>||</literal> </entry>
10793         <entry>array-to-element concatenation</entry>
10794         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
10795         <entry><literal>{4,5,6,7}</literal></entry>
10796        </row>
10797       </tbody>
10798      </tgroup>
10799     </table>
10800
10801   <para>
10802    Array comparisons compare the array contents element-by-element,
10803    using the default B-tree comparison function for the element data type.
10804    In multidimensional arrays the elements are visited in row-major order
10805    (last subscript varies most rapidly).
10806    If the contents of two arrays are equal but the dimensionality is
10807    different, the first difference in the dimensionality information
10808    determines the sort order.  (This is a change from versions of
10809    <productname>PostgreSQL</> prior to 8.2: older versions would claim
10810    that two arrays with the same contents were equal, even if the
10811    number of dimensions or subscript ranges were different.)
10812   </para>
10813
10814   <para>
10815    See <xref linkend="arrays"> for more details about array operator
10816    behavior.  See <xref linkend="indexes-types"> for more details about
10817    which operators support indexed operations.
10818   </para>
10819
10820   <para>
10821    <xref linkend="array-functions-table"> shows the functions
10822    available for use with array types. See <xref linkend="arrays">
10823    for more information  and examples of the use of these functions.
10824   </para>
10825
10826   <indexterm>
10827     <primary>array_append</primary>
10828   </indexterm>
10829   <indexterm>
10830     <primary>array_cat</primary>
10831   </indexterm>
10832   <indexterm>
10833     <primary>array_ndims</primary>
10834   </indexterm>
10835   <indexterm>
10836     <primary>array_dims</primary>
10837   </indexterm>
10838   <indexterm>
10839     <primary>array_fill</primary>
10840   </indexterm>
10841   <indexterm>
10842     <primary>array_length</primary>
10843   </indexterm>
10844   <indexterm>
10845     <primary>array_lower</primary>
10846   </indexterm>
10847   <indexterm>
10848     <primary>array_prepend</primary>
10849   </indexterm>
10850   <indexterm>
10851     <primary>array_remove</primary>
10852   </indexterm>
10853   <indexterm>
10854     <primary>array_replace</primary>
10855   </indexterm>
10856   <indexterm>
10857     <primary>array_to_string</primary>
10858   </indexterm>
10859  <indexterm>
10860     <primary>array_upper</primary>
10861   </indexterm>
10862   <indexterm>
10863     <primary>string_to_array</primary>
10864   </indexterm>
10865   <indexterm>
10866     <primary>unnest</primary>
10867   </indexterm>
10868
10869     <table id="array-functions-table">
10870      <title>Array Functions</title>
10871      <tgroup cols="5">
10872       <thead>
10873        <row>
10874         <entry>Function</entry>
10875         <entry>Return Type</entry>
10876         <entry>Description</entry>
10877         <entry>Example</entry>
10878         <entry>Result</entry>
10879        </row>
10880       </thead>
10881       <tbody>
10882        <row>
10883         <entry>
10884          <literal>
10885           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
10886          </literal>
10887         </entry>
10888         <entry><type>anyarray</type></entry>
10889         <entry>append an element to the end of an array</entry>
10890         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
10891         <entry><literal>{1,2,3}</literal></entry>
10892        </row>
10893        <row>
10894         <entry>
10895          <literal>
10896           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
10897          </literal>
10898         </entry>
10899         <entry><type>anyarray</type></entry>
10900         <entry>concatenate two arrays</entry>
10901         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
10902         <entry><literal>{1,2,3,4,5}</literal></entry>
10903        </row>
10904        <row>
10905         <entry>
10906          <literal>
10907           <function>array_ndims</function>(<type>anyarray</type>)
10908          </literal>
10909         </entry>
10910         <entry><type>int</type></entry>
10911         <entry>returns the number of dimensions of the array</entry>
10912         <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
10913         <entry><literal>2</literal></entry>
10914        </row>
10915        <row>
10916         <entry>
10917          <literal>
10918           <function>array_dims</function>(<type>anyarray</type>)
10919          </literal>
10920         </entry>
10921         <entry><type>text</type></entry>
10922         <entry>returns a text representation of array's dimensions</entry>
10923         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
10924         <entry><literal>[1:2][1:3]</literal></entry>
10925        </row>
10926        <row>
10927         <entry>
10928          <literal>
10929           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
10930           <optional>, <type>int[]</type></optional>)
10931          </literal>
10932         </entry>
10933         <entry><type>anyarray</type></entry>
10934         <entry>returns an array initialized with supplied value and
10935          dimensions, optionally with lower bounds other than 1</entry>
10936         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
10937         <entry><literal>[2:4]={7,7,7}</literal></entry>
10938        </row>
10939        <row>
10940         <entry>
10941          <literal>
10942           <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
10943          </literal>
10944         </entry>
10945         <entry><type>int</type></entry>
10946         <entry>returns the length of the requested array dimension</entry>
10947         <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
10948         <entry><literal>3</literal></entry>
10949        </row>
10950        <row>
10951         <entry>
10952          <literal>
10953           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
10954          </literal>
10955         </entry>
10956         <entry><type>int</type></entry>
10957         <entry>returns lower bound of the requested array dimension</entry>
10958         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
10959         <entry><literal>0</literal></entry>
10960        </row>
10961        <row>
10962         <entry>
10963          <literal>
10964           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
10965          </literal>
10966         </entry>
10967         <entry><type>anyarray</type></entry>
10968         <entry>append an element to the beginning of an array</entry>
10969         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
10970         <entry><literal>{1,2,3}</literal></entry>
10971        </row>
10972        <row>
10973         <entry>
10974          <literal>
10975           <function>array_remove</function>(<type>anyarray</type>, <type>anyelement</type>)
10976          </literal>
10977         </entry>
10978         <entry><type>anyarray</type></entry>
10979         <entry>remove all elements equal to the given value from the array
10980          (array must be one-dimensional)</entry>
10981         <entry><literal>array_remove(ARRAY[1,2,3,2], 2)</literal></entry>
10982         <entry><literal>{1,3}</literal></entry>
10983        </row>
10984        <row>
10985         <entry>
10986          <literal>
10987           <function>array_replace</function>(<type>anyarray</type>, <type>anyelement</type>, <type>anyelement</type>)
10988          </literal>
10989         </entry>
10990         <entry><type>anyarray</type></entry>
10991         <entry>replace each array element equal to the given value with a new value</entry>
10992         <entry><literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal></entry>
10993         <entry><literal>{1,2,3,4}</literal></entry>
10994        </row>
10995        <row>
10996         <entry>
10997          <literal>
10998           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type> <optional>, <type>text</type></optional>)
10999          </literal>
11000         </entry>
11001         <entry><type>text</type></entry>
11002         <entry>concatenates array elements using supplied delimiter and
11003          optional null string</entry>
11004         <entry><literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal></entry>
11005         <entry><literal>1,2,3,*,5</literal></entry>
11006        </row>
11007        <row>
11008         <entry>
11009          <literal>
11010           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
11011          </literal>
11012         </entry>
11013         <entry><type>int</type></entry>
11014         <entry>returns upper bound of the requested array dimension</entry>
11015         <entry><literal>array_upper(ARRAY[1,8,3,7], 1)</literal></entry>
11016         <entry><literal>4</literal></entry>
11017        </row>
11018        <row>
11019         <entry>
11020          <literal>
11021           <function>string_to_array</function>(<type>text</type>, <type>text</type> <optional>, <type>text</type></optional>)
11022          </literal>
11023         </entry>
11024         <entry><type>text[]</type></entry>
11025         <entry>splits string into array elements using supplied delimiter and
11026          optional null string</entry>
11027         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~', 'yy')</literal></entry>
11028         <entry><literal>{xx,NULL,zz}</literal></entry>
11029        </row>
11030        <row>
11031         <entry>
11032          <literal>
11033           <function>unnest</function>(<type>anyarray</type>)
11034          </literal>
11035         </entry>
11036         <entry><type>setof anyelement</type></entry>
11037         <entry>expand an array to a set of rows</entry>
11038         <entry><literal>unnest(ARRAY[1,2])</literal></entry>
11039         <entry><literallayout class="monospaced">1
11040 2</literallayout>(2 rows)</entry>
11041        </row>
11042       </tbody>
11043      </tgroup>
11044     </table>
11045
11046    <para>
11047     In <function>string_to_array</function>, if the delimiter parameter is
11048     NULL, each character in the input string will become a separate element in
11049     the resulting array.  If the delimiter is an empty string, then the entire
11050     input string is returned as a one-element array.  Otherwise the input
11051     string is split at each occurrence of the delimiter string.
11052    </para>
11053
11054    <para>
11055     In <function>string_to_array</function>, if the null-string parameter
11056     is omitted or NULL, none of the substrings of the input will be replaced
11057     by NULL.
11058     In <function>array_to_string</function>, if the null-string parameter
11059     is omitted or NULL, any null elements in the array are simply skipped
11060     and not represented in the output string.
11061    </para>
11062
11063    <note>
11064     <para>
11065      There are two differences in the behavior of <function>string_to_array</>
11066      from pre-9.1 versions of <productname>PostgreSQL</>.
11067      First, it will return an empty (zero-element) array rather than NULL when
11068      the input string is of zero length.  Second, if the delimiter string is
11069      NULL, the function splits the input into individual characters, rather
11070      than returning NULL as before.
11071     </para>
11072    </note>
11073
11074    <para>
11075     See also <xref linkend="functions-aggregate"> about the aggregate
11076     function <function>array_agg</function> for use with arrays.
11077    </para>
11078   </sect1>
11079
11080  <sect1 id="functions-range">
11081   <title>Range Functions and Operators</title>
11082
11083   <para>
11084    See <xref linkend="rangetypes"> for an overview of range types.
11085   </para>
11086
11087   <para>
11088    <xref linkend="range-operators-table"> shows the operators
11089    available for range types.
11090   </para>
11091
11092     <table id="range-operators-table">
11093      <title>Range Operators</title>
11094      <tgroup cols="4">
11095       <thead>
11096        <row>
11097         <entry>Operator</entry>
11098         <entry>Description</entry>
11099         <entry>Example</entry>
11100         <entry>Result</entry>
11101        </row>
11102       </thead>
11103       <tbody>
11104        <row>
11105         <entry> <literal>=</literal> </entry>
11106         <entry>equal</entry>
11107         <entry><literal>int4range(1,5) = '[1,4]'::int4range</literal></entry>
11108         <entry><literal>t</literal></entry>
11109        </row>
11110
11111        <row>
11112         <entry> <literal>&lt;&gt;</literal> </entry>
11113         <entry>not equal</entry>
11114         <entry><literal>numrange(1.1,2.2) &lt;&gt; numrange(1.1,2.3)</literal></entry>
11115         <entry><literal>t</literal></entry>
11116        </row>
11117
11118        <row>
11119         <entry> <literal>&lt;</literal> </entry>
11120         <entry>less than</entry>
11121         <entry><literal>int4range(1,10) &lt; int4range(2,3)</literal></entry>
11122         <entry><literal>t</literal></entry>
11123        </row>
11124
11125        <row>
11126         <entry> <literal>&gt;</literal> </entry>
11127         <entry>greater than</entry>
11128         <entry><literal>int4range(1,10) &gt; int4range(1,5)</literal></entry>
11129         <entry><literal>t</literal></entry>
11130        </row>
11131
11132        <row>
11133         <entry> <literal>&lt;=</literal> </entry>
11134         <entry>less than or equal</entry>
11135         <entry><literal>numrange(1.1,2.2) &lt;= numrange(1.1,2.2)</literal></entry>
11136         <entry><literal>t</literal></entry>
11137        </row>
11138
11139        <row>
11140         <entry> <literal>&gt;=</literal> </entry>
11141         <entry>greater than or equal</entry>
11142         <entry><literal>numrange(1.1,2.2) &gt;= numrange(1.1,2.0)</literal></entry>
11143         <entry><literal>t</literal></entry>
11144        </row>
11145
11146        <row>
11147         <entry> <literal>@&gt;</literal> </entry>
11148         <entry>contains range</entry>
11149         <entry><literal>int4range(2,4) @&gt; int4range(2,3)</literal></entry>
11150         <entry><literal>t</literal></entry>
11151        </row>
11152
11153        <row>
11154         <entry> <literal>@&gt;</literal> </entry>
11155         <entry>contains element</entry>
11156         <entry><literal>'[2011-01-01,2011-03-01)'::tsrange @&gt; '2011-01-10'::timestamp</literal></entry>
11157         <entry><literal>t</literal></entry>
11158        </row>
11159
11160        <row>
11161         <entry> <literal>&lt;@</literal> </entry>
11162         <entry>range is contained by</entry>
11163         <entry><literal>int4range(2,4) &lt;@ int4range(1,7)</literal></entry>
11164         <entry><literal>t</literal></entry>
11165        </row>
11166
11167        <row>
11168         <entry> <literal>&lt;@</literal> </entry>
11169         <entry>element is contained by</entry>
11170         <entry><literal>42 &lt;@ int4range(1,7)</literal></entry>
11171         <entry><literal>f</literal></entry>
11172        </row>
11173
11174        <row>
11175         <entry> <literal>&amp;&amp;</literal> </entry>
11176         <entry>overlap (have points in common)</entry>
11177         <entry><literal>int8range(3,7) &amp;&amp; int8range(4,12)</literal></entry>
11178         <entry><literal>t</literal></entry>
11179        </row>
11180
11181        <row>
11182         <entry> <literal>&lt;&lt;</literal> </entry>
11183         <entry>strictly left of</entry>
11184         <entry><literal>int8range(1,10) &lt;&lt; int8range(100,110)</literal></entry>
11185         <entry><literal>t</literal></entry>
11186        </row>
11187
11188        <row>
11189         <entry> <literal>&gt;&gt;</literal> </entry>
11190         <entry>strictly right of</entry>
11191         <entry><literal>int8range(50,60) &gt;&gt; int8range(20,30)</literal></entry>
11192         <entry><literal>t</literal></entry>
11193        </row>
11194
11195        <row>
11196         <entry> <literal>&amp;&lt;</literal> </entry>
11197         <entry>does not extend to the right of</entry>
11198         <entry><literal>int8range(1,20) &amp;&lt; int8range(18,20)</literal></entry>
11199         <entry><literal>t</literal></entry>
11200        </row>
11201
11202        <row>
11203         <entry> <literal>&amp;&gt;</literal> </entry>
11204         <entry>does not extend to the left of</entry>
11205         <entry><literal>int8range(7,20) &amp;&gt; int8range(5,10)</literal></entry>
11206         <entry><literal>t</literal></entry>
11207        </row>
11208
11209        <row>
11210         <entry> <literal>-|-</literal> </entry>
11211         <entry>is adjacent to</entry>
11212         <entry><literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal></entry>
11213         <entry><literal>t</literal></entry>
11214        </row>
11215
11216        <row>
11217         <entry> <literal>+</literal> </entry>
11218         <entry>union</entry>
11219         <entry><literal>numrange(5,15) + numrange(10,20)</literal></entry>
11220         <entry><literal>[5,20)</literal></entry>
11221        </row>
11222
11223        <row>
11224         <entry> <literal>*</literal> </entry>
11225         <entry>intersection</entry>
11226         <entry><literal>int8range(5,15) * int8range(10,20)</literal></entry>
11227         <entry><literal>[10,15)</literal></entry>
11228        </row>
11229
11230        <row>
11231         <entry> <literal>-</literal> </entry>
11232         <entry>difference</entry>
11233         <entry><literal>int8range(5,15) - int8range(10,20)</literal></entry>
11234         <entry><literal>[5,10)</literal></entry>
11235        </row>
11236
11237       </tbody>
11238      </tgroup>
11239     </table>
11240
11241   <para>
11242    The simple comparison operators <literal>&lt;</literal>,
11243    <literal>&gt;</literal>, <literal>&lt;=</literal>, and
11244    <literal>&gt;=</literal> compare the lower bounds first, and only if those
11245    are equal, compare the upper bounds.  These comparisons are not usually
11246    very useful for ranges, but are provided to allow B-tree indexes to be
11247    constructed on ranges.
11248   </para>
11249
11250   <para>
11251    The left-of/right-of/adjacent operators always return false when an empty
11252    range is involved; that is, an empty range is not considered to be either
11253    before or after any other range.
11254   </para>
11255
11256   <para>
11257    The union and difference operators will fail if the resulting range would
11258    need to contain two disjoint sub-ranges, as such a range cannot be
11259    represented.
11260   </para>
11261
11262   <para>
11263    <xref linkend="range-functions-table"> shows the functions
11264    available for use with range types.
11265   </para>
11266
11267   <indexterm>
11268     <primary>lower</primary>
11269   </indexterm>
11270   <indexterm>
11271     <primary>upper</primary>
11272   </indexterm>
11273   <indexterm>
11274     <primary>isempty</primary>
11275   </indexterm>
11276   <indexterm>
11277     <primary>lower_inc</primary>
11278   </indexterm>
11279   <indexterm>
11280     <primary>upper_inc</primary>
11281   </indexterm>
11282   <indexterm>
11283     <primary>lower_inf</primary>
11284   </indexterm>
11285   <indexterm>
11286     <primary>upper_inf</primary>
11287   </indexterm>
11288
11289     <table id="range-functions-table">
11290      <title>Range Functions</title>
11291      <tgroup cols="5">
11292       <thead>
11293        <row>
11294         <entry>Function</entry>
11295         <entry>Return Type</entry>
11296         <entry>Description</entry>
11297         <entry>Example</entry>
11298         <entry>Result</entry>
11299        </row>
11300       </thead>
11301       <tbody>
11302        <row>
11303         <entry>
11304          <literal>
11305           <function>lower</function>(<type>anyrange</type>)
11306          </literal>
11307         </entry>
11308         <entry>range's element type</entry>
11309         <entry>lower bound of range</entry>
11310         <entry><literal>lower(numrange(1.1,2.2))</literal></entry>
11311         <entry><literal>1.1</literal></entry>
11312        </row>
11313        <row>
11314         <entry>
11315          <literal>
11316           <function>upper</function>(<type>anyrange</type>)
11317          </literal>
11318         </entry>
11319         <entry>range's element type</entry>
11320         <entry>upper bound of range</entry>
11321         <entry><literal>upper(numrange(1.1,2.2))</literal></entry>
11322         <entry><literal>2.2</literal></entry>
11323        </row>
11324        <row>
11325         <entry>
11326          <literal>
11327           <function>isempty</function>(<type>anyrange</type>)
11328          </literal>
11329         </entry>
11330         <entry><type>boolean</type></entry>
11331         <entry>is the range empty?</entry>
11332         <entry><literal>isempty(numrange(1.1,2.2))</literal></entry>
11333         <entry><literal>false</literal></entry>
11334        </row>
11335        <row>
11336         <entry>
11337          <literal>
11338           <function>lower_inc</function>(<type>anyrange</type>)
11339          </literal>
11340         </entry>
11341         <entry><type>boolean</type></entry>
11342         <entry>is the lower bound inclusive?</entry>
11343         <entry><literal>lower_inc(numrange(1.1,2.2))</literal></entry>
11344         <entry><literal>true</literal></entry>
11345        </row>
11346        <row>
11347         <entry>
11348          <literal>
11349           <function>upper_inc</function>(<type>anyrange</type>)
11350          </literal>
11351         </entry>
11352         <entry><type>boolean</type></entry>
11353         <entry>is the upper bound inclusive?</entry>
11354         <entry><literal>upper_inc(numrange(1.1,2.2))</literal></entry>
11355         <entry><literal>false</literal></entry>
11356        </row>
11357        <row>
11358         <entry>
11359          <literal>
11360           <function>lower_inf</function>(<type>anyrange</type>)
11361          </literal>
11362         </entry>
11363         <entry><type>boolean</type></entry>
11364         <entry>is the lower bound infinite?</entry>
11365         <entry><literal>lower_inf('(,)'::daterange)</literal></entry>
11366         <entry><literal>true</literal></entry>
11367        </row>
11368        <row>
11369         <entry>
11370          <literal>
11371           <function>upper_inf</function>(<type>anyrange</type>)
11372          </literal>
11373         </entry>
11374         <entry><type>boolean</type></entry>
11375         <entry>is the upper bound infinite?</entry>
11376         <entry><literal>upper_inf('(,)'::daterange)</literal></entry>
11377         <entry><literal>true</literal></entry>
11378        </row>
11379       </tbody>
11380      </tgroup>
11381     </table>
11382
11383   <para>
11384    The <function>lower</> and  <function>upper</> functions return null
11385    if the range is empty or the requested bound is infinite.
11386    The <function>lower_inc</function>, <function>upper_inc</function>,
11387    <function>lower_inf</function>, and <function>upper_inf</function>
11388    functions all return false for an empty range.
11389   </para>
11390   </sect1>
11391
11392  <sect1 id="functions-aggregate">
11393   <title>Aggregate Functions</title>
11394
11395   <indexterm zone="functions-aggregate">
11396    <primary>aggregate function</primary>
11397    <secondary>built-in</secondary>
11398   </indexterm>
11399
11400   <para>
11401    <firstterm>Aggregate functions</firstterm> compute a single result
11402    from a set of input values.  The built-in aggregate functions
11403    are listed in
11404    <xref linkend="functions-aggregate-table"> and
11405    <xref linkend="functions-aggregate-statistics-table">.
11406    The special syntax considerations for aggregate
11407    functions are explained in <xref linkend="syntax-aggregates">.
11408    Consult <xref linkend="tutorial-agg"> for additional introductory
11409    information.
11410   </para>
11411
11412   <table id="functions-aggregate-table">
11413    <title>General-Purpose Aggregate Functions</title>
11414
11415    <tgroup cols="4">
11416     <thead>
11417      <row>
11418       <entry>Function</entry>
11419       <entry>Argument Type(s)</entry>
11420       <entry>Return Type</entry>
11421       <entry>Description</entry>
11422      </row>
11423     </thead>
11424
11425     <tbody>
11426      <row>
11427       <entry>
11428        <indexterm>
11429         <primary>array_agg</primary>
11430        </indexterm>
11431        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
11432       </entry>
11433       <entry>
11434        any
11435       </entry>
11436       <entry>
11437        array of the argument type
11438       </entry>
11439       <entry>input values, including nulls, concatenated into an array</entry>
11440      </row>
11441
11442      <row>
11443       <entry>
11444        <indexterm>
11445         <primary>average</primary>
11446        </indexterm>
11447        <indexterm>
11448         <primary>avg</primary>
11449        </indexterm>
11450        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
11451       </entry>
11452       <entry>
11453        <type>smallint</type>, <type>int</type>,
11454        <type>bigint</type>, <type>real</type>, <type>double
11455        precision</type>, <type>numeric</type>, or <type>interval</type>
11456       </entry>
11457       <entry>
11458        <type>numeric</type> for any integer-type argument,
11459        <type>double precision</type> for a floating-point argument,
11460        otherwise the same as the argument data type
11461       </entry>
11462       <entry>the average (arithmetic mean) of all input values</entry>
11463      </row>
11464
11465      <row>
11466       <entry>
11467        <indexterm>
11468         <primary>bit_and</primary>
11469        </indexterm>
11470        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
11471       </entry>
11472       <entry>
11473        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
11474        <type>bit</type>
11475       </entry>
11476       <entry>
11477         same as argument data type
11478       </entry>
11479       <entry>the bitwise AND of all non-null input values, or null if none</entry>
11480      </row>
11481
11482      <row>
11483       <entry>
11484        <indexterm>
11485         <primary>bit_or</primary>
11486        </indexterm>
11487        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
11488       </entry>
11489       <entry>
11490        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
11491        <type>bit</type>
11492       </entry>
11493       <entry>
11494         same as argument data type
11495       </entry>
11496       <entry>the bitwise OR of all non-null input values, or null if none</entry>
11497      </row>
11498
11499      <row>
11500       <entry>
11501        <indexterm>
11502         <primary>bool_and</primary>
11503        </indexterm>
11504        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
11505       </entry>
11506       <entry>
11507        <type>bool</type>
11508       </entry>
11509       <entry>
11510        <type>bool</type>
11511       </entry>
11512       <entry>true if all input values are true, otherwise false</entry>
11513      </row>
11514
11515      <row>
11516       <entry>
11517        <indexterm>
11518         <primary>bool_or</primary>
11519        </indexterm>
11520        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
11521       </entry>
11522       <entry>
11523        <type>bool</type>
11524       </entry>
11525       <entry>
11526        <type>bool</type>
11527       </entry>
11528       <entry>true if at least one input value is true, otherwise false</entry>
11529      </row>
11530
11531      <row>
11532       <entry>
11533        <indexterm>
11534         <primary>count</primary>
11535        </indexterm>
11536        <function>count(*)</function>
11537       </entry>
11538       <entry></entry>
11539       <entry><type>bigint</type></entry>
11540       <entry>number of input rows</entry>
11541      </row>
11542
11543      <row>
11544       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
11545       <entry>any</entry>
11546       <entry><type>bigint</type></entry>
11547       <entry>
11548        number of input rows for which the value of <replaceable
11549        class="parameter">expression</replaceable> is not null
11550       </entry>
11551      </row>
11552
11553      <row>
11554       <entry>
11555        <indexterm>
11556         <primary>every</primary>
11557        </indexterm>
11558        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
11559       </entry>
11560       <entry>
11561        <type>bool</type>
11562       </entry>
11563       <entry>
11564        <type>bool</type>
11565       </entry>
11566       <entry>equivalent to <function>bool_and</function></entry>
11567      </row>
11568
11569      <row>
11570       <entry>
11571        <indexterm>
11572         <primary>json_agg</primary>
11573        </indexterm>
11574        <function>json_agg(<replaceable class="parameter">record</replaceable>)</function>
11575       </entry>
11576       <entry>
11577        <type>record</type>
11578       </entry>
11579       <entry>
11580        <type>json</type>
11581       </entry>
11582       <entry>aggregates records as a JSON array of objects</entry>
11583      </row>
11584
11585      <row>
11586       <entry>
11587        <indexterm>
11588         <primary>max</primary>
11589        </indexterm>
11590        <function>max(<replaceable class="parameter">expression</replaceable>)</function>
11591       </entry>
11592       <entry>any array, numeric, string, or date/time type</entry>
11593       <entry>same as argument type</entry>
11594       <entry>
11595        maximum value of <replaceable
11596        class="parameter">expression</replaceable> across all input
11597        values
11598       </entry>
11599      </row>
11600
11601      <row>
11602       <entry>
11603        <indexterm>
11604         <primary>min</primary>
11605        </indexterm>
11606        <function>min(<replaceable class="parameter">expression</replaceable>)</function>
11607       </entry>
11608       <entry>any array, numeric, string, or date/time type</entry>
11609       <entry>same as argument type</entry>
11610       <entry>
11611        minimum value of <replaceable
11612        class="parameter">expression</replaceable> across all input
11613        values
11614       </entry>
11615      </row>
11616
11617      <row>
11618       <entry>
11619        <indexterm>
11620         <primary>string_agg</primary>
11621        </indexterm>
11622        <function>
11623          string_agg(<replaceable class="parameter">expression</replaceable>,
11624                     <replaceable class="parameter">delimiter</replaceable>)
11625        </function>
11626       </entry>
11627       <entry>
11628        (<type>text</type>, <type>text</type>) or (<type>bytea</type>, <type>bytea</type>)
11629       </entry>
11630       <entry>
11631        same as argument types
11632       </entry>
11633       <entry>input values concatenated into a string, separated by delimiter</entry>
11634      </row>
11635
11636      <row>
11637       <entry>
11638        <indexterm>
11639         <primary>sum</primary>
11640        </indexterm>
11641        <function>sum(<replaceable class="parameter">expression</replaceable>)</function>
11642       </entry>
11643       <entry>
11644        <type>smallint</type>, <type>int</type>,
11645        <type>bigint</type>, <type>real</type>, <type>double
11646        precision</type>, <type>numeric</type>, or
11647        <type>interval</type>
11648       </entry>
11649       <entry>
11650        <type>bigint</type> for <type>smallint</type> or
11651        <type>int</type> arguments, <type>numeric</type> for
11652        <type>bigint</type> arguments, <type>double precision</type>
11653        for floating-point arguments, otherwise the same as the
11654        argument data type
11655       </entry>
11656       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
11657      </row>
11658
11659      <row>
11660       <entry>
11661        <indexterm>
11662         <primary>xmlagg</primary>
11663        </indexterm>
11664        <function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
11665       </entry>
11666       <entry>
11667        <type>xml</type>
11668       </entry>
11669       <entry>
11670        <type>xml</type>
11671       </entry>
11672       <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
11673      </row>
11674     </tbody>
11675    </tgroup>
11676   </table>
11677
11678   <para>
11679    It should be noted that except for <function>count</function>,
11680    these functions return a null value when no rows are selected.  In
11681    particular, <function>sum</function> of no rows returns null, not
11682    zero as one might expect, and <function>array_agg</function>
11683    returns null rather than an empty array when there are no input
11684    rows.  The <function>coalesce</function> function can be used to
11685    substitute zero or an empty array for null when necessary.
11686   </para>
11687
11688   <note>
11689     <indexterm>
11690       <primary>ANY</primary>
11691     </indexterm>
11692     <indexterm>
11693       <primary>SOME</primary>
11694     </indexterm>
11695     <para>
11696       Boolean aggregates <function>bool_and</function> and
11697       <function>bool_or</function> correspond to standard SQL aggregates
11698       <function>every</function> and <function>any</function> or
11699       <function>some</function>.
11700       As for <function>any</function> and <function>some</function>,
11701       it seems that there is an ambiguity built into the standard syntax:
11702 <programlisting>
11703 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
11704 </programlisting>
11705       Here <function>ANY</function> can be considered either as introducing
11706       a subquery, or as being an aggregate function, if the subquery
11707       returns one row with a Boolean value.
11708       Thus the standard name cannot be given to these aggregates.
11709     </para>
11710   </note>
11711
11712   <note>
11713    <para>
11714     Users accustomed to working with other SQL database management
11715     systems might be disappointed by the performance of the
11716     <function>count</function> aggregate when it is applied to the
11717     entire table. A query like:
11718 <programlisting>
11719 SELECT count(*) FROM sometable;
11720 </programlisting>
11721     will require effort proportional to the size of the table:
11722     <productname>PostgreSQL</productname> will need to scan either the
11723     entire table or the entirety of an index which includes all rows in
11724     the table.
11725    </para>
11726   </note>
11727
11728   <para>
11729    The aggregate functions <function>array_agg</function>,
11730    <function>json_agg</function>,
11731    <function>string_agg</function>,
11732    and <function>xmlagg</function>, as well as similar user-defined
11733    aggregate functions, produce meaningfully different result values
11734    depending on the order of the input values.  This ordering is
11735    unspecified by default, but can be controlled by writing an
11736    <literal>ORDER BY</> clause within the aggregate call, as shown in
11737    <xref linkend="syntax-aggregates">.
11738    Alternatively, supplying the input values from a sorted subquery
11739    will usually work.  For example:
11740
11741 <screen><![CDATA[
11742 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
11743 ]]></screen>
11744
11745    But this syntax is not allowed in the SQL standard, and is
11746    not portable to other database systems.
11747   </para>
11748
11749   <para>
11750    <xref linkend="functions-aggregate-statistics-table"> shows
11751    aggregate functions typically used in statistical analysis.
11752    (These are separated out merely to avoid cluttering the listing
11753    of more-commonly-used aggregates.)  Where the description mentions
11754    <replaceable class="parameter">N</replaceable>, it means the
11755    number of input rows for which all the input expressions are non-null.
11756    In all cases, null is returned if the computation is meaningless,
11757    for example when <replaceable class="parameter">N</replaceable> is zero.
11758   </para>
11759
11760   <indexterm>
11761    <primary>statistics</primary>
11762   </indexterm>
11763   <indexterm>
11764    <primary>linear regression</primary>
11765   </indexterm>
11766
11767   <table id="functions-aggregate-statistics-table">
11768    <title>Aggregate Functions for Statistics</title>
11769
11770    <tgroup cols="4">
11771     <thead>
11772      <row>
11773       <entry>Function</entry>
11774       <entry>Argument Type</entry>
11775       <entry>Return Type</entry>
11776       <entry>Description</entry>
11777      </row>
11778     </thead>
11779
11780     <tbody>
11781
11782      <row>
11783       <entry>
11784        <indexterm>
11785         <primary>correlation</primary>
11786        </indexterm>
11787        <indexterm>
11788         <primary>corr</primary>
11789        </indexterm>
11790        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11791       </entry>
11792       <entry>
11793        <type>double precision</type>
11794       </entry>
11795       <entry>
11796        <type>double precision</type>
11797       </entry>
11798       <entry>correlation coefficient</entry>
11799      </row>
11800
11801      <row>
11802       <entry>
11803        <indexterm>
11804         <primary>covariance</primary>
11805         <secondary>population</secondary>
11806        </indexterm>
11807        <indexterm>
11808         <primary>covar_pop</primary>
11809        </indexterm>
11810        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11811       </entry>
11812       <entry>
11813        <type>double precision</type>
11814       </entry>
11815       <entry>
11816        <type>double precision</type>
11817       </entry>
11818       <entry>population covariance</entry>
11819      </row>
11820
11821      <row>
11822       <entry>
11823        <indexterm>
11824         <primary>covariance</primary>
11825         <secondary>sample</secondary>
11826        </indexterm>
11827        <indexterm>
11828         <primary>covar_samp</primary>
11829        </indexterm>
11830        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11831       </entry>
11832       <entry>
11833        <type>double precision</type>
11834       </entry>
11835       <entry>
11836        <type>double precision</type>
11837       </entry>
11838       <entry>sample covariance</entry>
11839      </row>
11840
11841      <row>
11842       <entry>
11843        <indexterm>
11844         <primary>regr_avgx</primary>
11845        </indexterm>
11846        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11847       </entry>
11848       <entry>
11849        <type>double precision</type>
11850       </entry>
11851       <entry>
11852        <type>double precision</type>
11853       </entry>
11854       <entry>average of the independent variable
11855       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
11856      </row>
11857
11858      <row>
11859       <entry>
11860        <indexterm>
11861         <primary>regr_avgy</primary>
11862        </indexterm>
11863        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11864       </entry>
11865       <entry>
11866        <type>double precision</type>
11867       </entry>
11868       <entry>
11869        <type>double precision</type>
11870       </entry>
11871       <entry>average of the dependent variable
11872       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
11873      </row>
11874
11875      <row>
11876       <entry>
11877        <indexterm>
11878         <primary>regr_count</primary>
11879        </indexterm>
11880        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11881       </entry>
11882       <entry>
11883        <type>double precision</type>
11884       </entry>
11885       <entry>
11886        <type>bigint</type>
11887       </entry>
11888       <entry>number of input rows in which both expressions are nonnull</entry>
11889      </row>
11890
11891      <row>
11892       <entry>
11893        <indexterm>
11894         <primary>regression intercept</primary>
11895        </indexterm>
11896        <indexterm>
11897         <primary>regr_intercept</primary>
11898        </indexterm>
11899        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11900       </entry>
11901       <entry>
11902        <type>double precision</type>
11903       </entry>
11904       <entry>
11905        <type>double precision</type>
11906       </entry>
11907       <entry>y-intercept of the least-squares-fit linear equation
11908       determined by the (<replaceable
11909       class="parameter">X</replaceable>, <replaceable
11910       class="parameter">Y</replaceable>) pairs</entry>
11911      </row>
11912
11913      <row>
11914       <entry>
11915        <indexterm>
11916         <primary>regr_r2</primary>
11917        </indexterm>
11918        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11919       </entry>
11920       <entry>
11921        <type>double precision</type>
11922       </entry>
11923       <entry>
11924        <type>double precision</type>
11925       </entry>
11926       <entry>square of the correlation coefficient</entry>
11927      </row>
11928
11929      <row>
11930       <entry>
11931        <indexterm>
11932         <primary>regression slope</primary>
11933        </indexterm>
11934        <indexterm>
11935         <primary>regr_slope</primary>
11936        </indexterm>
11937        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11938       </entry>
11939       <entry>
11940        <type>double precision</type>
11941       </entry>
11942       <entry>
11943        <type>double precision</type>
11944       </entry>
11945       <entry>slope of the least-squares-fit linear equation determined
11946       by the (<replaceable class="parameter">X</replaceable>,
11947       <replaceable class="parameter">Y</replaceable>) pairs</entry>
11948      </row>
11949
11950      <row>
11951       <entry>
11952        <indexterm>
11953         <primary>regr_sxx</primary>
11954        </indexterm>
11955        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11956       </entry>
11957       <entry>
11958        <type>double precision</type>
11959       </entry>
11960       <entry>
11961        <type>double precision</type>
11962       </entry>
11963       <entry><literal>sum(<replaceable
11964       class="parameter">X</replaceable>^2) - sum(<replaceable
11965       class="parameter">X</replaceable>)^2/<replaceable
11966       class="parameter">N</replaceable></literal> (<quote>sum of
11967       squares</quote> of the independent variable)</entry>
11968      </row>
11969
11970      <row>
11971       <entry>
11972        <indexterm>
11973         <primary>regr_sxy</primary>
11974        </indexterm>
11975        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11976       </entry>
11977       <entry>
11978        <type>double precision</type>
11979       </entry>
11980       <entry>
11981        <type>double precision</type>
11982       </entry>
11983       <entry><literal>sum(<replaceable
11984       class="parameter">X</replaceable>*<replaceable
11985       class="parameter">Y</replaceable>) - sum(<replaceable
11986       class="parameter">X</replaceable>) * sum(<replaceable
11987       class="parameter">Y</replaceable>)/<replaceable
11988       class="parameter">N</replaceable></literal> (<quote>sum of
11989       products</quote> of independent times dependent
11990       variable)</entry>
11991      </row>
11992
11993      <row>
11994       <entry>
11995        <indexterm>
11996         <primary>regr_syy</primary>
11997        </indexterm>
11998        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11999       </entry>
12000       <entry>
12001        <type>double precision</type>
12002       </entry>
12003       <entry>
12004        <type>double precision</type>
12005       </entry>
12006       <entry><literal>sum(<replaceable
12007       class="parameter">Y</replaceable>^2) - sum(<replaceable
12008       class="parameter">Y</replaceable>)^2/<replaceable
12009       class="parameter">N</replaceable></literal> (<quote>sum of
12010       squares</quote> of the dependent variable)</entry>
12011      </row>
12012
12013      <row>
12014       <entry>
12015        <indexterm>
12016         <primary>standard deviation</primary>
12017        </indexterm>
12018        <indexterm>
12019         <primary>stddev</primary>
12020        </indexterm>
12021        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
12022       </entry>
12023       <entry>
12024        <type>smallint</type>, <type>int</type>,
12025        <type>bigint</type>, <type>real</type>, <type>double
12026        precision</type>, or <type>numeric</type>
12027       </entry>
12028       <entry>
12029        <type>double precision</type> for floating-point arguments,
12030        otherwise <type>numeric</type>
12031       </entry>
12032       <entry>historical alias for <function>stddev_samp</function></entry>
12033      </row>
12034
12035      <row>
12036       <entry>
12037        <indexterm>
12038         <primary>standard deviation</primary>
12039         <secondary>population</secondary>
12040        </indexterm>
12041        <indexterm>
12042         <primary>stddev_pop</primary>
12043        </indexterm>
12044        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
12045       </entry>
12046       <entry>
12047        <type>smallint</type>, <type>int</type>,
12048        <type>bigint</type>, <type>real</type>, <type>double
12049        precision</type>, or <type>numeric</type>
12050       </entry>
12051       <entry>
12052        <type>double precision</type> for floating-point arguments,
12053        otherwise <type>numeric</type>
12054       </entry>
12055       <entry>population standard deviation of the input values</entry>
12056      </row>
12057
12058      <row>
12059       <entry>
12060        <indexterm>
12061         <primary>standard deviation</primary>
12062         <secondary>sample</secondary>
12063        </indexterm>
12064        <indexterm>
12065         <primary>stddev_samp</primary>
12066        </indexterm>
12067        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
12068       </entry>
12069       <entry>
12070        <type>smallint</type>, <type>int</type>,
12071        <type>bigint</type>, <type>real</type>, <type>double
12072        precision</type>, or <type>numeric</type>
12073       </entry>
12074       <entry>
12075        <type>double precision</type> for floating-point arguments,
12076        otherwise <type>numeric</type>
12077       </entry>
12078       <entry>sample standard deviation of the input values</entry>
12079      </row>
12080
12081      <row>
12082       <entry>
12083        <indexterm>
12084         <primary>variance</primary>
12085        </indexterm>
12086        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
12087       </entry>
12088       <entry>
12089        <type>smallint</type>, <type>int</type>,
12090        <type>bigint</type>, <type>real</type>, <type>double
12091        precision</type>, or <type>numeric</type>
12092       </entry>
12093       <entry>
12094        <type>double precision</type> for floating-point arguments,
12095        otherwise <type>numeric</type>
12096       </entry>
12097       <entry>historical alias for <function>var_samp</function></entry>
12098      </row>
12099
12100      <row>
12101       <entry>
12102        <indexterm>
12103         <primary>variance</primary>
12104         <secondary>population</secondary>
12105        </indexterm>
12106        <indexterm>
12107         <primary>var_pop</primary>
12108        </indexterm>
12109        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
12110       </entry>
12111       <entry>
12112        <type>smallint</type>, <type>int</type>,
12113        <type>bigint</type>, <type>real</type>, <type>double
12114        precision</type>, or <type>numeric</type>
12115       </entry>
12116       <entry>
12117        <type>double precision</type> for floating-point arguments,
12118        otherwise <type>numeric</type>
12119       </entry>
12120       <entry>population variance of the input values (square of the population standard deviation)</entry>
12121      </row>
12122
12123      <row>
12124       <entry>
12125        <indexterm>
12126         <primary>variance</primary>
12127         <secondary>sample</secondary>
12128        </indexterm>
12129        <indexterm>
12130         <primary>var_samp</primary>
12131        </indexterm>
12132        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
12133       </entry>
12134       <entry>
12135        <type>smallint</type>, <type>int</type>,
12136        <type>bigint</type>, <type>real</type>, <type>double
12137        precision</type>, or <type>numeric</type>
12138       </entry>
12139       <entry>
12140        <type>double precision</type> for floating-point arguments,
12141        otherwise <type>numeric</type>
12142       </entry>
12143       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
12144      </row>
12145     </tbody>
12146    </tgroup>
12147   </table>
12148
12149  </sect1>
12150
12151  <sect1 id="functions-window">
12152   <title>Window Functions</title>
12153
12154   <indexterm zone="functions-window">
12155    <primary>window function</primary>
12156    <secondary>built-in</secondary>
12157   </indexterm>
12158
12159   <para>
12160    <firstterm>Window functions</firstterm> provide the ability to perform
12161    calculations across sets of rows that are related to the current query
12162    row.  See <xref linkend="tutorial-window"> for an introduction to this
12163    feature.
12164   </para>
12165
12166   <para>
12167    The built-in window functions are listed in
12168    <xref linkend="functions-window-table">.  Note that these functions
12169    <emphasis>must</> be invoked using window function syntax; that is an
12170    <literal>OVER</> clause is required.
12171   </para>
12172
12173   <para>
12174    In addition to these functions, any built-in or user-defined aggregate
12175    function can be used as a window function (see
12176    <xref linkend="functions-aggregate"> for a list of the built-in aggregates).
12177    Aggregate functions act as window functions only when an <literal>OVER</>
12178    clause follows the call; otherwise they act as regular aggregates.
12179   </para>
12180
12181   <table id="functions-window-table">
12182    <title>General-Purpose Window Functions</title>
12183
12184    <tgroup cols="3">
12185     <thead>
12186      <row>
12187       <entry>Function</entry>
12188       <entry>Return Type</entry>
12189       <entry>Description</entry>
12190      </row>
12191     </thead>
12192
12193     <tbody>
12194      <row>
12195       <entry>
12196        <indexterm>
12197         <primary>row_number</primary>
12198        </indexterm>
12199        <function>row_number()</function>
12200       </entry>
12201       <entry>
12202        <type>bigint</type>
12203       </entry>
12204       <entry>number of the current row within its partition, counting from 1</entry>
12205      </row>
12206
12207      <row>
12208       <entry>
12209        <indexterm>
12210         <primary>rank</primary>
12211        </indexterm>
12212        <function>rank()</function>
12213       </entry>
12214       <entry>
12215        <type>bigint</type>
12216       </entry>
12217       <entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
12218      </row>
12219
12220      <row>
12221       <entry>
12222        <indexterm>
12223         <primary>dense_rank</primary>
12224        </indexterm>
12225        <function>dense_rank()</function>
12226       </entry>
12227       <entry>
12228        <type>bigint</type>
12229       </entry>
12230       <entry>rank of the current row without gaps; this function counts peer groups</entry>
12231      </row>
12232
12233      <row>
12234       <entry>
12235        <indexterm>
12236         <primary>percent_rank</primary>
12237        </indexterm>
12238        <function>percent_rank()</function>
12239       </entry>
12240       <entry>
12241        <type>double precision</type>
12242       </entry>
12243       <entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
12244      </row>
12245
12246      <row>
12247       <entry>
12248        <indexterm>
12249         <primary>cume_dist</primary>
12250        </indexterm>
12251        <function>cume_dist()</function>
12252       </entry>
12253       <entry>
12254        <type>double precision</type>
12255       </entry>
12256       <entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
12257      </row>
12258
12259      <row>
12260       <entry>
12261        <indexterm>
12262         <primary>ntile</primary>
12263        </indexterm>
12264        <function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</>)</function>
12265       </entry>
12266       <entry>
12267        <type>integer</type>
12268       </entry>
12269       <entry>integer ranging from 1 to the argument value, dividing the
12270        partition as equally as possible</entry>
12271      </row>
12272
12273      <row>
12274       <entry>
12275        <indexterm>
12276         <primary>lag</primary>
12277        </indexterm>
12278        <function>
12279          lag(<replaceable class="parameter">value</replaceable> <type>any</>
12280              [, <replaceable class="parameter">offset</replaceable> <type>integer</>
12281              [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
12282        </function>
12283       </entry>
12284       <entry>
12285        <type>same type as <replaceable class="parameter">value</replaceable></type>
12286       </entry>
12287       <entry>
12288        returns <replaceable class="parameter">value</replaceable> evaluated at
12289        the row that is <replaceable class="parameter">offset</replaceable>
12290        rows before the current row within the partition; if there is no such
12291        row, instead return <replaceable class="parameter">default</replaceable>.
12292        Both <replaceable class="parameter">offset</replaceable> and
12293        <replaceable class="parameter">default</replaceable> are evaluated
12294        with respect to the current row.  If omitted,
12295        <replaceable class="parameter">offset</replaceable> defaults to 1 and
12296        <replaceable class="parameter">default</replaceable> to null
12297       </entry>
12298      </row>
12299
12300      <row>
12301       <entry>
12302        <indexterm>
12303         <primary>lead</primary>
12304        </indexterm>
12305        <function>
12306          lead(<replaceable class="parameter">value</replaceable> <type>any</>
12307               [, <replaceable class="parameter">offset</replaceable> <type>integer</>
12308               [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
12309        </function>
12310       </entry>
12311       <entry>
12312        <type>same type as <replaceable class="parameter">value</replaceable></type>
12313       </entry>
12314       <entry>
12315        returns <replaceable class="parameter">value</replaceable> evaluated at
12316        the row that is <replaceable class="parameter">offset</replaceable>
12317        rows after the current row within the partition; if there is no such
12318        row, instead return <replaceable class="parameter">default</replaceable>.
12319        Both <replaceable class="parameter">offset</replaceable> and
12320        <replaceable class="parameter">default</replaceable> are evaluated
12321        with respect to the current row.  If omitted,
12322        <replaceable class="parameter">offset</replaceable> defaults to 1 and
12323        <replaceable class="parameter">default</replaceable> to null
12324       </entry>
12325      </row>
12326
12327      <row>
12328       <entry>
12329        <indexterm>
12330         <primary>first_value</primary>
12331        </indexterm>
12332        <function>first_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
12333       </entry>
12334       <entry>
12335        <type>same type as <replaceable class="parameter">value</replaceable></type>
12336       </entry>
12337       <entry>
12338        returns <replaceable class="parameter">value</replaceable> evaluated
12339        at the row that is the first row of the window frame
12340       </entry>
12341      </row>
12342
12343      <row>
12344       <entry>
12345        <indexterm>
12346         <primary>last_value</primary>
12347        </indexterm>
12348        <function>last_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
12349       </entry>
12350       <entry>
12351        <type>same type as <replaceable class="parameter">value</replaceable></type>
12352       </entry>
12353       <entry>
12354        returns <replaceable class="parameter">value</replaceable> evaluated
12355        at the row that is the last row of the window frame
12356       </entry>
12357      </row>
12358
12359      <row>
12360       <entry>
12361        <indexterm>
12362         <primary>nth_value</primary>
12363        </indexterm>
12364        <function>
12365          nth_value(<replaceable class="parameter">value</replaceable> <type>any</>, <replaceable class="parameter">nth</replaceable> <type>integer</>)
12366        </function>
12367       </entry>
12368       <entry>
12369        <type>same type as <replaceable class="parameter">value</replaceable></type>
12370       </entry>
12371       <entry>
12372        returns <replaceable class="parameter">value</replaceable> evaluated
12373        at the row that is the <replaceable class="parameter">nth</replaceable>
12374        row of the window frame (counting from 1); null if no such row
12375       </entry>
12376      </row>
12377     </tbody>
12378    </tgroup>
12379   </table>
12380
12381   <para>
12382    All of the functions listed in
12383    <xref linkend="functions-window-table"> depend on the sort ordering
12384    specified by the <literal>ORDER BY</> clause of the associated window
12385    definition.  Rows that are not distinct in the <literal>ORDER BY</>
12386    ordering are said to be <firstterm>peers</>; the four ranking functions
12387    are defined so that they give the same answer for any two peer rows.
12388   </para>
12389
12390   <para>
12391    Note that <function>first_value</>, <function>last_value</>, and
12392    <function>nth_value</> consider only the rows within the <quote>window
12393    frame</>, which by default contains the rows from the start of the
12394    partition through the last peer of the current row.  This is
12395    likely to give unhelpful results for <function>last_value</> and
12396    sometimes also <function>nth_value</>.  You can redefine the frame by
12397    adding a suitable frame specification (<literal>RANGE</> or
12398    <literal>ROWS</>) to the <literal>OVER</> clause.
12399    See <xref linkend="syntax-window-functions"> for more information
12400    about frame specifications.
12401   </para>
12402
12403   <para>
12404    When an aggregate function is used as a window function, it aggregates
12405    over the rows within the current row's window frame.
12406    An aggregate used with <literal>ORDER BY</> and the default window frame
12407    definition produces a <quote>running sum</> type of behavior, which may or
12408    may not be what's wanted.  To obtain
12409    aggregation over the whole partition, omit <literal>ORDER BY</> or use
12410    <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
12411    Other frame specifications can be used to obtain other effects.
12412   </para>
12413
12414   <note>
12415    <para>
12416     The SQL standard defines a <literal>RESPECT NULLS</> or
12417     <literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
12418     <function>first_value</>, <function>last_value</>, and
12419     <function>nth_value</>.  This is not implemented in
12420     <productname>PostgreSQL</productname>: the behavior is always the
12421     same as the standard's default, namely <literal>RESPECT NULLS</>.
12422     Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
12423     option for <function>nth_value</> is not implemented: only the
12424     default <literal>FROM FIRST</> behavior is supported.  (You can achieve
12425     the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
12426     ordering.)
12427    </para>
12428   </note>
12429
12430  </sect1>
12431
12432  <sect1 id="functions-subquery">
12433   <title>Subquery Expressions</title>
12434
12435   <indexterm>
12436    <primary>EXISTS</primary>
12437   </indexterm>
12438
12439   <indexterm>
12440    <primary>IN</primary>
12441   </indexterm>
12442
12443   <indexterm>
12444    <primary>NOT IN</primary>
12445   </indexterm>
12446
12447   <indexterm>
12448    <primary>ANY</primary>
12449   </indexterm>
12450
12451   <indexterm>
12452    <primary>ALL</primary>
12453   </indexterm>
12454
12455   <indexterm>
12456    <primary>SOME</primary>
12457   </indexterm>
12458
12459   <indexterm>
12460    <primary>subquery</primary>
12461   </indexterm>
12462
12463   <para>
12464    This section describes the <acronym>SQL</acronym>-compliant subquery
12465    expressions available in <productname>PostgreSQL</productname>.
12466    All of the expression forms documented in this section return
12467    Boolean (true/false) results.
12468   </para>
12469
12470   <sect2 id="functions-subquery-exists">
12471    <title><literal>EXISTS</literal></title>
12472
12473 <synopsis>
12474 EXISTS (<replaceable>subquery</replaceable>)
12475 </synopsis>
12476
12477   <para>
12478    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
12479    or <firstterm>subquery</firstterm>.  The
12480    subquery is evaluated to determine whether it returns any rows.
12481    If it returns at least one row, the result of <token>EXISTS</token> is
12482    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
12483    is <quote>false</>.
12484   </para>
12485
12486   <para>
12487    The subquery can refer to variables from the surrounding query,
12488    which will act as constants during any one evaluation of the subquery.
12489   </para>
12490
12491   <para>
12492    The subquery will generally only be executed long enough to determine
12493    whether at least one row is returned, not all the way to completion.
12494    It is unwise to write a subquery that has side effects (such as
12495    calling sequence functions); whether the side effects occur
12496    might be unpredictable.
12497   </para>
12498
12499   <para>
12500    Since the result depends only on whether any rows are returned,
12501    and not on the contents of those rows, the output list of the
12502    subquery is normally unimportant.  A common coding convention is
12503    to write all <literal>EXISTS</> tests in the form
12504    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
12505    this rule however, such as subqueries that use <token>INTERSECT</token>.
12506   </para>
12507
12508   <para>
12509    This simple example is like an inner join on <literal>col2</>, but
12510    it produces at most one output row for each <literal>tab1</> row,
12511    even if there are several matching <literal>tab2</> rows:
12512 <screen>
12513 SELECT col1
12514 FROM tab1
12515 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
12516 </screen>
12517   </para>
12518   </sect2>
12519
12520   <sect2 id="functions-subquery-in">
12521    <title><literal>IN</literal></title>
12522
12523 <synopsis>
12524 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
12525 </synopsis>
12526
12527   <para>
12528    The right-hand side is a parenthesized
12529    subquery, which must return exactly one column.  The left-hand expression
12530    is evaluated and compared to each row of the subquery result.
12531    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
12532    The result is <quote>false</> if no equal row is found (including the
12533    case where the subquery returns no rows).
12534   </para>
12535
12536   <para>
12537    Note that if the left-hand expression yields null, or if there are
12538    no equal right-hand values and at least one right-hand row yields
12539    null, the result of the <token>IN</token> construct will be null, not false.
12540    This is in accordance with SQL's normal rules for Boolean combinations
12541    of null values.
12542   </para>
12543
12544   <para>
12545    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
12546    be evaluated completely.
12547   </para>
12548
12549 <synopsis>
12550 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
12551 </synopsis>
12552
12553   <para>
12554    The left-hand side of this form of <token>IN</token> is a row constructor,
12555    as described in <xref linkend="sql-syntax-row-constructors">.
12556    The right-hand side is a parenthesized
12557    subquery, which must return exactly as many columns as there are
12558    expressions in the left-hand row.  The left-hand expressions are
12559    evaluated and compared row-wise to each row of the subquery result.
12560    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
12561    The result is <quote>false</> if no equal row is found (including the
12562    case where the subquery returns no rows).
12563   </para>
12564
12565   <para>
12566    As usual, null values in the rows are combined per
12567    the normal rules of SQL Boolean expressions.  Two rows are considered
12568    equal if all their corresponding members are non-null and equal; the rows
12569    are unequal if any corresponding members are non-null and unequal;
12570    otherwise the result of that row comparison is unknown (null).
12571    If all the per-row results are either unequal or null, with at least one
12572    null, then the result of <token>IN</token> is null.
12573   </para>
12574   </sect2>
12575
12576   <sect2 id="functions-subquery-notin">
12577    <title><literal>NOT IN</literal></title>
12578
12579 <synopsis>
12580 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
12581 </synopsis>
12582
12583   <para>
12584    The right-hand side is a parenthesized
12585    subquery, which must return exactly one column.  The left-hand expression
12586    is evaluated and compared to each row of the subquery result.
12587    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
12588    are found (including the case where the subquery returns no rows).
12589    The result is <quote>false</> if any equal row is found.
12590   </para>
12591
12592   <para>
12593    Note that if the left-hand expression yields null, or if there are
12594    no equal right-hand values and at least one right-hand row yields
12595    null, the result of the <token>NOT IN</token> construct will be null, not true.
12596    This is in accordance with SQL's normal rules for Boolean combinations
12597    of null values.
12598   </para>
12599
12600   <para>
12601    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
12602    be evaluated completely.
12603   </para>
12604
12605 <synopsis>
12606 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
12607 </synopsis>
12608
12609   <para>
12610    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
12611    as described in <xref linkend="sql-syntax-row-constructors">.
12612    The right-hand side is a parenthesized
12613    subquery, which must return exactly as many columns as there are
12614    expressions in the left-hand row.  The left-hand expressions are
12615    evaluated and compared row-wise to each row of the subquery result.
12616    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
12617    are found (including the case where the subquery returns no rows).
12618    The result is <quote>false</> if any equal row is found.
12619   </para>
12620
12621   <para>
12622    As usual, null values in the rows are combined per
12623    the normal rules of SQL Boolean expressions.  Two rows are considered
12624    equal if all their corresponding members are non-null and equal; the rows
12625    are unequal if any corresponding members are non-null and unequal;
12626    otherwise the result of that row comparison is unknown (null).
12627    If all the per-row results are either unequal or null, with at least one
12628    null, then the result of <token>NOT IN</token> is null.
12629   </para>
12630   </sect2>
12631
12632   <sect2 id="functions-subquery-any-some">
12633    <title><literal>ANY</literal>/<literal>SOME</literal></title>
12634
12635 <synopsis>
12636 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
12637 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
12638 </synopsis>
12639
12640   <para>
12641    The right-hand side is a parenthesized
12642    subquery, which must return exactly one column.  The left-hand expression
12643    is evaluated and compared to each row of the subquery result using the
12644    given <replaceable>operator</replaceable>, which must yield a Boolean
12645    result.
12646    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
12647    The result is <quote>false</> if no true result is found (including the
12648    case where the subquery returns no rows).
12649   </para>
12650
12651   <para>
12652    <token>SOME</token> is a synonym for <token>ANY</token>.
12653    <token>IN</token> is equivalent to <literal>= ANY</literal>.
12654   </para>
12655
12656   <para>
12657    Note that if there are no successes and at least one right-hand row yields
12658    null for the operator's result, the result of the <token>ANY</token> construct
12659    will be null, not false.
12660    This is in accordance with SQL's normal rules for Boolean combinations
12661    of null values.
12662   </para>
12663
12664   <para>
12665    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
12666    be evaluated completely.
12667   </para>
12668
12669 <synopsis>
12670 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
12671 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
12672 </synopsis>
12673
12674   <para>
12675    The left-hand side of this form of <token>ANY</token> is a row constructor,
12676    as described in <xref linkend="sql-syntax-row-constructors">.
12677    The right-hand side is a parenthesized
12678    subquery, which must return exactly as many columns as there are
12679    expressions in the left-hand row.  The left-hand expressions are
12680    evaluated and compared row-wise to each row of the subquery result,
12681    using the given <replaceable>operator</replaceable>.
12682    The result of <token>ANY</token> is <quote>true</> if the comparison
12683    returns true for any subquery row.
12684    The result is <quote>false</> if the comparison returns false for every
12685    subquery row (including the case where the subquery returns no
12686    rows).
12687    The result is NULL if the comparison does not return true for any row,
12688    and it returns NULL for at least one row.
12689   </para>
12690
12691   <para>
12692    See <xref linkend="row-wise-comparison"> for details about the meaning
12693    of a row-wise comparison.
12694   </para>
12695   </sect2>
12696
12697   <sect2 id="functions-subquery-all">
12698    <title><literal>ALL</literal></title>
12699
12700 <synopsis>
12701 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
12702 </synopsis>
12703
12704   <para>
12705    The right-hand side is a parenthesized
12706    subquery, which must return exactly one column.  The left-hand expression
12707    is evaluated and compared to each row of the subquery result using the
12708    given <replaceable>operator</replaceable>, which must yield a Boolean
12709    result.
12710    The result of <token>ALL</token> is <quote>true</> if all rows yield true
12711    (including the case where the subquery returns no rows).
12712    The result is <quote>false</> if any false result is found.
12713    The result is NULL if the comparison does not return false for any row,
12714    and it returns NULL for at least one row.
12715   </para>
12716
12717   <para>
12718    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
12719   </para>
12720
12721   <para>
12722    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
12723    be evaluated completely.
12724   </para>
12725
12726 <synopsis>
12727 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
12728 </synopsis>
12729
12730   <para>
12731    The left-hand side of this form of <token>ALL</token> is a row constructor,
12732    as described in <xref linkend="sql-syntax-row-constructors">.
12733    The right-hand side is a parenthesized
12734    subquery, which must return exactly as many columns as there are
12735    expressions in the left-hand row.  The left-hand expressions are
12736    evaluated and compared row-wise to each row of the subquery result,
12737    using the given <replaceable>operator</replaceable>.
12738    The result of <token>ALL</token> is <quote>true</> if the comparison
12739    returns true for all subquery rows (including the
12740    case where the subquery returns no rows).
12741    The result is <quote>false</> if the comparison returns false for any
12742    subquery row.
12743    The result is NULL if the comparison does not return false for any
12744    subquery row, and it returns NULL for at least one row.
12745   </para>
12746
12747   <para>
12748    See <xref linkend="row-wise-comparison"> for details about the meaning
12749    of a row-wise comparison.
12750   </para>
12751   </sect2>
12752
12753   <sect2>
12754    <title>Row-wise Comparison</title>
12755
12756    <indexterm zone="functions-subquery">
12757     <primary>comparison</primary>
12758     <secondary>subquery result row</secondary>
12759    </indexterm>
12760
12761 <synopsis>
12762 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
12763 </synopsis>
12764
12765   <para>
12766    The left-hand side is a row constructor,
12767    as described in <xref linkend="sql-syntax-row-constructors">.
12768    The right-hand side is a parenthesized subquery, which must return exactly
12769    as many columns as there are expressions in the left-hand row. Furthermore,
12770    the subquery cannot return more than one row.  (If it returns zero rows,
12771    the result is taken to be null.)  The left-hand side is evaluated and
12772    compared row-wise to the single subquery result row.
12773   </para>
12774
12775   <para>
12776    See <xref linkend="row-wise-comparison"> for details about the meaning
12777    of a row-wise comparison.
12778   </para>
12779   </sect2>
12780  </sect1>
12781
12782
12783  <sect1 id="functions-comparisons">
12784   <title>Row and Array Comparisons</title>
12785
12786   <indexterm>
12787    <primary>IN</primary>
12788   </indexterm>
12789
12790   <indexterm>
12791    <primary>NOT IN</primary>
12792   </indexterm>
12793
12794   <indexterm>
12795    <primary>ANY</primary>
12796   </indexterm>
12797
12798   <indexterm>
12799    <primary>ALL</primary>
12800   </indexterm>
12801
12802   <indexterm>
12803    <primary>SOME</primary>
12804   </indexterm>
12805
12806   <indexterm>
12807    <primary>row-wise comparison</primary>
12808   </indexterm>
12809
12810   <indexterm>
12811    <primary>comparison</primary>
12812    <secondary>row-wise</secondary>
12813   </indexterm>
12814
12815   <indexterm>
12816    <primary>IS DISTINCT FROM</primary>
12817   </indexterm>
12818
12819   <indexterm>
12820    <primary>IS NOT DISTINCT FROM</primary>
12821   </indexterm>
12822
12823   <para>
12824    This section describes several specialized constructs for making
12825    multiple comparisons between groups of values.  These forms are
12826    syntactically related to the subquery forms of the previous section,
12827    but do not involve subqueries.
12828    The forms involving array subexpressions are
12829    <productname>PostgreSQL</productname> extensions; the rest are
12830    <acronym>SQL</acronym>-compliant.
12831    All of the expression forms documented in this section return
12832    Boolean (true/false) results.
12833   </para>
12834
12835   <sect2>
12836    <title><literal>IN</literal></title>
12837
12838 <synopsis>
12839 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
12840 </synopsis>
12841
12842   <para>
12843    The right-hand side is a parenthesized list
12844    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
12845    result is equal to any of the right-hand expressions.  This is a shorthand
12846    notation for
12847
12848 <synopsis>
12849 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
12850 OR
12851 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
12852 OR
12853 ...
12854 </synopsis>
12855   </para>
12856
12857   <para>
12858    Note that if the left-hand expression yields null, or if there are
12859    no equal right-hand values and at least one right-hand expression yields
12860    null, the result of the <token>IN</token> construct will be null, not false.
12861    This is in accordance with SQL's normal rules for Boolean combinations
12862    of null values.
12863   </para>
12864   </sect2>
12865
12866   <sect2>
12867    <title><literal>NOT IN</literal></title>
12868
12869 <synopsis>
12870 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
12871 </synopsis>
12872
12873   <para>
12874    The right-hand side is a parenthesized list
12875    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
12876    result is unequal to all of the right-hand expressions.  This is a shorthand
12877    notation for
12878
12879 <synopsis>
12880 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
12881 AND
12882 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
12883 AND
12884 ...
12885 </synopsis>
12886   </para>
12887
12888   <para>
12889    Note that if the left-hand expression yields null, or if there are
12890    no equal right-hand values and at least one right-hand expression yields
12891    null, the result of the <token>NOT IN</token> construct will be null, not true
12892    as one might naively expect.
12893    This is in accordance with SQL's normal rules for Boolean combinations
12894    of null values.
12895   </para>
12896
12897   <tip>
12898   <para>
12899    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
12900    cases.  However, null values are much more likely to trip up the novice when
12901    working with <token>NOT IN</token> than when working with <token>IN</token>.
12902    It is best to express your condition positively if possible.
12903   </para>
12904   </tip>
12905   </sect2>
12906
12907   <sect2>
12908    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
12909
12910 <synopsis>
12911 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
12912 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
12913 </synopsis>
12914
12915   <para>
12916    The right-hand side is a parenthesized expression, which must yield an
12917    array value.
12918    The left-hand expression
12919    is evaluated and compared to each element of the array using the
12920    given <replaceable>operator</replaceable>, which must yield a Boolean
12921    result.
12922    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
12923    The result is <quote>false</> if no true result is found (including the
12924    case where the array has zero elements).
12925   </para>
12926
12927   <para>
12928    If the array expression yields a null array, the result of
12929    <token>ANY</token> will be null.  If the left-hand expression yields null,
12930    the result of <token>ANY</token> is ordinarily null (though a non-strict
12931    comparison operator could possibly yield a different result).
12932    Also, if the right-hand array contains any null elements and no true
12933    comparison result is obtained, the result of <token>ANY</token>
12934    will be null, not false (again, assuming a strict comparison operator).
12935    This is in accordance with SQL's normal rules for Boolean combinations
12936    of null values.
12937   </para>
12938
12939   <para>
12940    <token>SOME</token> is a synonym for <token>ANY</token>.
12941   </para>
12942   </sect2>
12943
12944   <sect2>
12945    <title><literal>ALL</literal> (array)</title>
12946
12947 <synopsis>
12948 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
12949 </synopsis>
12950
12951   <para>
12952    The right-hand side is a parenthesized expression, which must yield an
12953    array value.
12954    The left-hand expression
12955    is evaluated and compared to each element of the array using the
12956    given <replaceable>operator</replaceable>, which must yield a Boolean
12957    result.
12958    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
12959    (including the case where the array has zero elements).
12960    The result is <quote>false</> if any false result is found.
12961   </para>
12962
12963   <para>
12964    If the array expression yields a null array, the result of
12965    <token>ALL</token> will be null.  If the left-hand expression yields null,
12966    the result of <token>ALL</token> is ordinarily null (though a non-strict
12967    comparison operator could possibly yield a different result).
12968    Also, if the right-hand array contains any null elements and no false
12969    comparison result is obtained, the result of <token>ALL</token>
12970    will be null, not true (again, assuming a strict comparison operator).
12971    This is in accordance with SQL's normal rules for Boolean combinations
12972    of null values.
12973   </para>
12974   </sect2>
12975
12976   <sect2 id="row-wise-comparison">
12977    <title>Row-wise Comparison</title>
12978
12979 <synopsis>
12980 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
12981 </synopsis>
12982
12983   <para>
12984    Each side is a row constructor,
12985    as described in <xref linkend="sql-syntax-row-constructors">.
12986    The two row values must have the same number of fields.
12987    Each side is evaluated and they are compared row-wise.  Row comparisons
12988    are allowed when the <replaceable>operator</replaceable> is
12989    <literal>=</>,
12990    <literal>&lt;&gt;</>,
12991    <literal>&lt;</>,
12992    <literal>&lt;=</>,
12993    <literal>&gt;</> or
12994    <literal>&gt;=</>,
12995    or has semantics similar to one of these.  (To be specific, an operator
12996    can be a row comparison operator if it is a member of a B-tree operator
12997    class, or is the negator of the <literal>=</> member of a B-tree operator
12998    class.)
12999   </para>
13000
13001   <para>
13002    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
13003    from the others.  Two rows are considered
13004    equal if all their corresponding members are non-null and equal; the rows
13005    are unequal if any corresponding members are non-null and unequal;
13006    otherwise the result of the row comparison is unknown (null).
13007   </para>
13008
13009   <para>
13010    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
13011    <literal>&gt;=</> cases, the row elements are compared left-to-right,
13012    stopping as soon as an unequal or null pair of elements is found.
13013    If either of this pair of elements is null, the result of the
13014    row comparison is unknown (null); otherwise comparison of this pair
13015    of elements determines the result.  For example,
13016    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
13017    yields true, not null, because the third pair of elements are not
13018    considered.
13019   </para>
13020
13021   <note>
13022    <para>
13023     Prior to <productname>PostgreSQL</productname> 8.2, the
13024     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
13025     cases were not handled per SQL specification.  A comparison like
13026     <literal>ROW(a,b) &lt; ROW(c,d)</>
13027     was implemented as
13028     <literal>a &lt; c AND b &lt; d</>
13029     whereas the correct behavior is equivalent to
13030     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
13031    </para>
13032   </note>
13033
13034 <synopsis>
13035 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
13036 </synopsis>
13037
13038   <para>
13039    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
13040    but it does not yield null for null inputs.  Instead, any null value is
13041    considered unequal to (distinct from) any non-null value, and any two
13042    nulls are considered equal (not distinct).  Thus the result will
13043    either be true or false, never null.
13044   </para>
13045
13046 <synopsis>
13047 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
13048 </synopsis>
13049
13050   <para>
13051    This construct is similar to a <literal>=</literal> row comparison,
13052    but it does not yield null for null inputs.  Instead, any null value is
13053    considered unequal to (distinct from) any non-null value, and any two
13054    nulls are considered equal (not distinct).  Thus the result will always
13055    be either true or false, never null.
13056   </para>
13057
13058   <note>
13059    <para>
13060     The SQL specification requires row-wise comparison to return NULL if the
13061     result depends on comparing two NULL values or a NULL and a non-NULL.
13062     <productname>PostgreSQL</productname> does this only when comparing the
13063     results of two row constructors or comparing a row constructor to the
13064     output of a subquery (as in <xref linkend="functions-subquery">).
13065     In other contexts where two composite-type values are compared, two
13066     NULL field values are considered equal, and a NULL is considered larger
13067     than a non-NULL.  This is necessary in order to have consistent sorting
13068     and indexing behavior for composite types.
13069    </para>
13070   </note>
13071
13072   </sect2>
13073  </sect1>
13074
13075  <sect1 id="functions-srf">
13076   <title>Set Returning Functions</title>
13077
13078   <indexterm zone="functions-srf">
13079    <primary>set returning functions</primary>
13080    <secondary>functions</secondary>
13081   </indexterm>
13082
13083   <indexterm>
13084    <primary>generate_series</primary>
13085   </indexterm>
13086
13087   <para>
13088    This section describes functions that possibly return more than one row.
13089    The most widely used functions in this class are series generating
13090    functions, as detailed in <xref linkend="functions-srf-series"> and
13091    <xref linkend="functions-srf-subscripts">.  Other, more specialized
13092    set-returning functions are described elsewhere in this manual.
13093   </para>
13094
13095   <table id="functions-srf-series">
13096    <title>Series Generating Functions</title>
13097    <tgroup cols="4">
13098     <thead>
13099      <row>
13100       <entry>Function</entry>
13101       <entry>Argument Type</entry>
13102       <entry>Return Type</entry>
13103       <entry>Description</entry>
13104      </row>
13105     </thead>
13106
13107     <tbody>
13108      <row>
13109       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>)</function></literal></entry>
13110       <entry><type>int</type> or <type>bigint</type></entry>
13111       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
13112       <entry>
13113        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
13114        with a step size of one
13115       </entry>
13116      </row>
13117
13118      <row>
13119       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</function></literal></entry>
13120       <entry><type>int</type> or <type>bigint</type></entry>
13121       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
13122       <entry>
13123        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
13124        with a step size of <parameter>step</parameter>
13125       </entry>
13126      </row>
13127
13128      <row>
13129       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</function></literal></entry>
13130       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
13131       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
13132       <entry>
13133        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
13134        with a step size of <parameter>step</parameter>
13135       </entry>
13136      </row>
13137
13138     </tbody>
13139    </tgroup>
13140   </table>
13141
13142   <para>
13143    When <parameter>step</parameter> is positive, zero rows are returned if
13144    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
13145    Conversely, when <parameter>step</parameter> is negative, zero rows are
13146    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
13147    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
13148    for <parameter>step</parameter> to be zero. Some examples follow:
13149 <programlisting>
13150 SELECT * FROM generate_series(2,4);
13151  generate_series
13152 -----------------
13153                2
13154                3
13155                4
13156 (3 rows)
13157
13158 SELECT * FROM generate_series(5,1,-2);
13159  generate_series
13160 -----------------
13161                5
13162                3
13163                1
13164 (3 rows)
13165
13166 SELECT * FROM generate_series(4,3);
13167  generate_series
13168 -----------------
13169 (0 rows)
13170
13171 -- this example relies on the date-plus-integer operator
13172 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
13173    dates
13174 ------------
13175  2004-02-05
13176  2004-02-12
13177  2004-02-19
13178 (3 rows)
13179
13180 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
13181                               '2008-03-04 12:00', '10 hours');
13182    generate_series   
13183 ---------------------
13184  2008-03-01 00:00:00
13185  2008-03-01 10:00:00
13186  2008-03-01 20:00:00
13187  2008-03-02 06:00:00
13188  2008-03-02 16:00:00
13189  2008-03-03 02:00:00
13190  2008-03-03 12:00:00
13191  2008-03-03 22:00:00
13192  2008-03-04 08:00:00
13193 (9 rows)
13194 </programlisting>
13195   </para>
13196
13197   <table id="functions-srf-subscripts">
13198    <title>Subscript Generating Functions</title>
13199    <tgroup cols="3">
13200     <thead>
13201      <row>
13202       <entry>Function</entry>
13203       <entry>Return Type</entry>
13204       <entry>Description</entry>
13205      </row>
13206     </thead>
13207
13208     <tbody>
13209      <row>
13210       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</function></literal></entry>
13211       <entry><type>setof int</type></entry>
13212       <entry>
13213        Generate a series comprising the given array's subscripts.
13214       </entry>
13215      </row>
13216
13217      <row>
13218       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</function></literal></entry>
13219       <entry><type>setof int</type></entry>
13220       <entry>
13221        Generate a series comprising the given array's subscripts. When
13222        <parameter>reverse</parameter> is true, the series is returned in
13223        reverse order.
13224       </entry>
13225      </row>
13226
13227     </tbody>
13228    </tgroup>
13229   </table>
13230
13231   <indexterm>
13232    <primary>generate_subscripts</primary>
13233   </indexterm>
13234
13235   <para>
13236    <function>generate_subscripts</> is a convenience function that generates
13237    the set of valid subscripts for the specified dimension of the given
13238    array.
13239    Zero rows are returned for arrays that do not have the requested dimension,
13240    or for NULL arrays (but valid subscripts are returned for NULL array
13241    elements).  Some examples follow:
13242 <programlisting>
13243 -- basic usage
13244 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
13245  s 
13246 ---
13247  1
13248  2
13249  3
13250  4
13251 (4 rows)
13252
13253 -- presenting an array, the subscript and the subscripted
13254 -- value requires a subquery
13255 SELECT * FROM arrays;
13256          a          
13257 --------------------
13258  {-1,-2}
13259  {100,200,300}
13260 (2 rows)
13261
13262 SELECT a AS array, s AS subscript, a[s] AS value
13263 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
13264      array     | subscript | value
13265 ---------------+-----------+-------
13266  {-1,-2}       |         1 |    -1
13267  {-1,-2}       |         2 |    -2
13268  {100,200,300} |         1 |   100
13269  {100,200,300} |         2 |   200
13270  {100,200,300} |         3 |   300
13271 (5 rows)
13272
13273 -- unnest a 2D array
13274 CREATE OR REPLACE FUNCTION unnest2(anyarray)
13275 RETURNS SETOF anyelement AS $$
13276 select $1[i][j]
13277    from generate_subscripts($1,1) g1(i),
13278         generate_subscripts($1,2) g2(j);
13279 $$ LANGUAGE sql IMMUTABLE;
13280 CREATE FUNCTION
13281 postgres=# SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
13282  unnest2 
13283 ---------
13284        1
13285        2
13286        3
13287        4
13288 (4 rows)
13289 </programlisting>
13290   </para>
13291
13292  </sect1>
13293
13294  <sect1 id="functions-info">
13295   <title>System Information Functions</title>
13296
13297   <para>
13298    <xref linkend="functions-info-session-table"> shows several
13299    functions that extract session and system information.
13300   </para>
13301
13302   <para>
13303    In addition to the functions listed in this section, there are a number of
13304    functions related to the statistics system that also provide system
13305    information. See <xref linkend="monitoring-stats-views"> for more
13306    information.
13307   </para>
13308
13309    <table id="functions-info-session-table">
13310     <title>Session Information Functions</title>
13311     <tgroup cols="3">
13312      <thead>
13313       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13314      </thead>
13315
13316      <tbody>
13317       <row>
13318        <entry><literal><function>current_catalog</function></literal></entry>
13319        <entry><type>name</type></entry>
13320        <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
13321       </row>
13322
13323       <row>
13324        <entry><literal><function>current_database()</function></literal></entry>
13325        <entry><type>name</type></entry>
13326        <entry>name of current database</entry>
13327       </row>
13328
13329       <row>
13330        <entry><literal><function>current_query()</function></literal></entry>
13331        <entry><type>text</type></entry>
13332        <entry>text of the currently executing query, as submitted
13333        by the client (might contain more than one statement)</entry>
13334       </row>
13335
13336       <row>
13337        <entry><literal><function>current_schema</function>[()]</literal></entry>
13338        <entry><type>name</type></entry>
13339        <entry>name of current schema</entry>
13340       </row>
13341
13342       <row>
13343        <entry><literal><function>current_schemas(<type>boolean</type>)</function></literal></entry>
13344        <entry><type>name[]</type></entry>
13345        <entry>names of schemas in search path, optionally including implicit schemas</entry>
13346       </row>
13347
13348       <row>
13349        <entry><literal><function>current_user</function></literal></entry>
13350        <entry><type>name</type></entry>
13351        <entry>user name of current execution context</entry>
13352       </row>
13353
13354       <row>
13355        <entry><literal><function>inet_client_addr()</function></literal></entry>
13356        <entry><type>inet</type></entry>
13357        <entry>address of the remote connection</entry>
13358       </row>
13359
13360       <row>
13361        <entry><literal><function>inet_client_port()</function></literal></entry>
13362        <entry><type>int</type></entry>
13363        <entry>port of the remote connection</entry>
13364       </row>
13365
13366       <row>
13367        <entry><literal><function>inet_server_addr()</function></literal></entry>
13368        <entry><type>inet</type></entry>
13369        <entry>address of the local connection</entry>
13370       </row>
13371
13372       <row>
13373        <entry><literal><function>inet_server_port()</function></literal></entry>
13374        <entry><type>int</type></entry>
13375        <entry>port of the local connection</entry>
13376       </row>
13377
13378       <row>
13379        <!-- See also the entry for this in monitoring.sgml -->
13380        <entry><literal><function>pg_backend_pid()</function></literal></entry>
13381        <entry><type>int</type></entry>
13382        <entry>
13383         Process ID of the server process attached to the current session
13384        </entry>
13385       </row>
13386
13387       <row>
13388        <entry><literal><function>pg_conf_load_time()</function></literal></entry>
13389        <entry><type>timestamp with time zone</type></entry>
13390        <entry>configuration load time</entry>
13391       </row>
13392
13393       <row>
13394        <entry><literal><function>pg_is_other_temp_schema(<type>oid</type>)</function></literal></entry>
13395        <entry><type>boolean</type></entry>
13396        <entry>is schema another session's temporary schema?</entry>
13397       </row>
13398
13399       <row>
13400        <entry><literal><function>pg_listening_channels()</function></literal></entry>
13401        <entry><type>setof text</type></entry>
13402        <entry>channel names that the session is currently listening on</entry>
13403       </row>
13404
13405       <row>
13406        <entry><literal><function>pg_my_temp_schema()</function></literal></entry>
13407        <entry><type>oid</type></entry>
13408        <entry>OID of session's temporary schema, or 0 if none</entry>
13409       </row>
13410
13411       <row>
13412        <entry><literal><function>pg_postmaster_start_time()</function></literal></entry>
13413        <entry><type>timestamp with time zone</type></entry>
13414        <entry>server start time</entry>
13415       </row>
13416
13417       <row>
13418        <entry><literal><function>pg_trigger_depth()</function></literal></entry>
13419        <entry><type>int</type></entry>
13420        <entry>current nesting level of <productname>PostgreSQL</> triggers
13421        (0 if not called, directly or indirectly, from inside a trigger)</entry>
13422       </row>
13423
13424       <row>
13425        <entry><literal><function>session_user</function></literal></entry>
13426        <entry><type>name</type></entry>
13427        <entry>session user name</entry>
13428       </row>
13429
13430       <row>
13431        <entry><literal><function>user</function></literal></entry>
13432        <entry><type>name</type></entry>
13433        <entry>equivalent to <function>current_user</function></entry>
13434       </row>
13435
13436       <row>
13437        <entry><literal><function>version()</function></literal></entry>
13438        <entry><type>text</type></entry>
13439        <entry><productname>PostgreSQL</> version information</entry>
13440       </row>
13441      </tbody>
13442     </tgroup>
13443    </table>
13444
13445    <note>
13446     <para>
13447      <function>current_catalog</function>, <function>current_schema</function>,
13448      <function>current_user</function>, <function>session_user</function>,
13449      and <function>user</function> have special syntactic status
13450      in <acronym>SQL</acronym>: they must be called without trailing
13451      parentheses.  (In PostgreSQL, parentheses can optionally be used with
13452      <function>current_schema</function>, but not with the others.)
13453     </para>
13454    </note>
13455
13456    <indexterm>
13457     <primary>current_catalog</primary>
13458    </indexterm>
13459
13460    <indexterm>
13461     <primary>current_database</primary>
13462    </indexterm>
13463
13464    <indexterm>
13465     <primary>current_query</primary>
13466    </indexterm>
13467
13468    <indexterm>
13469     <primary>current_schema</primary>
13470    </indexterm>
13471
13472    <indexterm>
13473     <primary>current_schemas</primary>
13474    </indexterm>
13475
13476    <indexterm>
13477     <primary>current_user</primary>
13478    </indexterm>
13479
13480    <indexterm>
13481     <primary>pg_backend_pid</primary>
13482    </indexterm>
13483
13484    <indexterm>
13485     <primary>schema</primary>
13486     <secondary>current</secondary>
13487    </indexterm>
13488
13489    <indexterm>
13490     <primary>search path</primary>
13491     <secondary>current</secondary>
13492    </indexterm>
13493
13494    <indexterm>
13495     <primary>session_user</primary>
13496    </indexterm>
13497
13498    <indexterm>
13499     <primary>user</primary>
13500     <secondary>current</secondary>
13501    </indexterm>
13502
13503    <indexterm>
13504     <primary>user</primary>
13505    </indexterm>
13506
13507    <para>
13508     The <function>session_user</function> is normally the user who initiated
13509     the current database connection; but superusers can change this setting
13510     with <xref linkend="sql-set-session-authorization">.
13511     The <function>current_user</function> is the user identifier
13512     that is applicable for permission checking. Normally it is equal
13513     to the session user, but it can be changed with
13514     <xref linkend="sql-set-role">.
13515     It also changes during the execution of
13516     functions with the attribute <literal>SECURITY DEFINER</literal>.
13517     In Unix parlance, the session user is the <quote>real user</quote> and
13518     the current user is the <quote>effective user</quote>.
13519    </para>
13520
13521    <para>
13522     <function>current_schema</function> returns the name of the schema that is
13523     first in the search path (or a null value if the search path is
13524     empty).  This is the schema that will be used for any tables or
13525     other named objects that are created without specifying a target schema.
13526     <function>current_schemas(boolean)</function> returns an array of the names of all
13527     schemas presently in the search path.  The Boolean option determines whether or not
13528     implicitly included system schemas such as <literal>pg_catalog</> are included in the
13529     returned search path.
13530    </para>
13531
13532    <note>
13533     <para>
13534      The search path can be altered at run time.  The command is:
13535 <programlisting>
13536 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
13537 </programlisting>
13538     </para>
13539    </note>
13540
13541    <indexterm>
13542     <primary>pg_listening_channels</primary>
13543    </indexterm>
13544
13545    <para>
13546     <function>pg_listening_channels</function> returns a set of names of
13547     channels that the current session is listening to.  See <xref
13548     linkend="sql-listen"> for more information.
13549    </para>
13550
13551    <indexterm>
13552     <primary>inet_client_addr</primary>
13553    </indexterm>
13554
13555    <indexterm>
13556     <primary>inet_client_port</primary>
13557    </indexterm>
13558
13559    <indexterm>
13560     <primary>inet_server_addr</primary>
13561    </indexterm>
13562
13563    <indexterm>
13564     <primary>inet_server_port</primary>
13565    </indexterm>
13566
13567    <para>
13568      <function>inet_client_addr</function> returns the IP address of the
13569      current client, and <function>inet_client_port</function> returns the
13570      port number.
13571      <function>inet_server_addr</function> returns the IP address on which
13572      the server accepted the current connection, and
13573      <function>inet_server_port</function> returns the port number.
13574      All these functions return NULL if the current connection is via a
13575      Unix-domain socket.
13576    </para>
13577
13578    <indexterm>
13579     <primary>pg_my_temp_schema</primary>
13580    </indexterm>
13581
13582    <indexterm>
13583     <primary>pg_is_other_temp_schema</primary>
13584    </indexterm>
13585
13586    <para>
13587     <function>pg_my_temp_schema</function> returns the OID of the current
13588     session's temporary schema, or zero if it has none (because it has not
13589     created any temporary tables).
13590     <function>pg_is_other_temp_schema</function> returns true if the
13591     given OID is the OID of another session's temporary schema.
13592     (This can be useful, for example, to exclude other sessions' temporary
13593     tables from a catalog display.)
13594    </para>
13595
13596    <indexterm>
13597     <primary>pg_postmaster_start_time</primary>
13598    </indexterm>
13599
13600    <para>
13601     <function>pg_postmaster_start_time</function> returns the
13602     <type>timestamp with time zone</type> when the
13603     server started.
13604    </para>
13605
13606    <indexterm>
13607     <primary>pg_conf_load_time</primary>
13608    </indexterm>
13609
13610    <para>
13611     <function>pg_conf_load_time</function> returns the
13612     <type>timestamp with time zone</type> when the
13613     server configuration files were last loaded.
13614     (If the current session was alive at the time, this will be the time
13615     when the session itself re-read the configuration files, so the
13616     reading will vary a little in different sessions.  Otherwise it is
13617     the time when the postmaster process re-read the configuration files.)
13618    </para>
13619
13620    <indexterm>
13621     <primary>version</primary>
13622    </indexterm>
13623
13624    <para>
13625     <function>version</function> returns a string describing the
13626     <productname>PostgreSQL</productname> server's version.
13627    </para>
13628
13629   <indexterm>
13630    <primary>privilege</primary>
13631    <secondary>querying</secondary>
13632   </indexterm>
13633
13634   <para>
13635    <xref linkend="functions-info-access-table"> lists functions that
13636    allow the user to query object access privileges programmatically.
13637    See <xref linkend="ddl-priv"> for more information about
13638    privileges.
13639   </para>
13640
13641    <table id="functions-info-access-table">
13642     <title>Access Privilege Inquiry Functions</title>
13643     <tgroup cols="3">
13644      <thead>
13645       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13646      </thead>
13647
13648      <tbody>
13649       <row>
13650        <entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
13651                                   <parameter>table</parameter>,
13652                                   <parameter>privilege</parameter>)</literal>
13653        </entry>
13654        <entry><type>boolean</type></entry>
13655        <entry>does user have privilege for any column of table</entry>
13656       </row>
13657       <row>
13658        <entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
13659                                   <parameter>privilege</parameter>)</literal>
13660        </entry>
13661        <entry><type>boolean</type></entry>
13662        <entry>does current user have privilege for any column of table</entry>
13663       </row>
13664       <row>
13665        <entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
13666                                   <parameter>table</parameter>,
13667                                   <parameter>column</parameter>,
13668                                   <parameter>privilege</parameter>)</literal>
13669        </entry>
13670        <entry><type>boolean</type></entry>
13671        <entry>does user have privilege for column</entry>
13672       </row>
13673       <row>
13674        <entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
13675                                   <parameter>column</parameter>,
13676                                   <parameter>privilege</parameter>)</literal>
13677        </entry>
13678        <entry><type>boolean</type></entry>
13679        <entry>does current user have privilege for column</entry>
13680       </row>
13681       <row>
13682        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
13683                                   <parameter>database</parameter>,
13684                                   <parameter>privilege</parameter>)</literal>
13685        </entry>
13686        <entry><type>boolean</type></entry>
13687        <entry>does user have privilege for database</entry>
13688       </row>
13689       <row>
13690        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
13691                                   <parameter>privilege</parameter>)</literal>
13692        </entry>
13693        <entry><type>boolean</type></entry>
13694        <entry>does current user have privilege for database</entry>
13695       </row>
13696       <row>
13697        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
13698                                   <parameter>fdw</parameter>,
13699                                   <parameter>privilege</parameter>)</literal>
13700        </entry>
13701        <entry><type>boolean</type></entry>
13702        <entry>does user have privilege for foreign-data wrapper</entry>
13703       </row>
13704       <row>
13705        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
13706                                   <parameter>privilege</parameter>)</literal>
13707        </entry>
13708        <entry><type>boolean</type></entry>
13709        <entry>does current user have privilege for foreign-data wrapper</entry>
13710       </row>
13711       <row>
13712        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
13713                                   <parameter>function</parameter>,
13714                                   <parameter>privilege</parameter>)</literal>
13715        </entry>
13716        <entry><type>boolean</type></entry>
13717        <entry>does user have privilege for function</entry>
13718       </row>
13719       <row>
13720        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
13721                                   <parameter>privilege</parameter>)</literal>
13722        </entry>
13723        <entry><type>boolean</type></entry>
13724        <entry>does current user have privilege for function</entry>
13725       </row>
13726       <row>
13727        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
13728                                   <parameter>language</parameter>,
13729                                   <parameter>privilege</parameter>)</literal>
13730        </entry>
13731        <entry><type>boolean</type></entry>
13732        <entry>does user have privilege for language</entry>
13733       </row>
13734       <row>
13735        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
13736                                   <parameter>privilege</parameter>)</literal>
13737        </entry>
13738        <entry><type>boolean</type></entry>
13739        <entry>does current user have privilege for language</entry>
13740       </row>
13741       <row>
13742        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
13743                                   <parameter>schema</parameter>,
13744                                   <parameter>privilege</parameter>)</literal>
13745        </entry>
13746        <entry><type>boolean</type></entry>
13747        <entry>does user have privilege for schema</entry>
13748       </row>
13749       <row>
13750        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
13751                                   <parameter>privilege</parameter>)</literal>
13752        </entry>
13753        <entry><type>boolean</type></entry>
13754        <entry>does current user have privilege for schema</entry>
13755       </row>
13756       <row>
13757        <entry><literal><function>has_sequence_privilege</function>(<parameter>user</parameter>,
13758                                   <parameter>sequence</parameter>,
13759                                   <parameter>privilege</parameter>)</literal>
13760        </entry>
13761        <entry><type>boolean</type></entry>
13762        <entry>does user have privilege for sequence</entry>
13763       </row>
13764       <row>
13765        <entry><literal><function>has_sequence_privilege</function>(<parameter>sequence</parameter>,
13766                                   <parameter>privilege</parameter>)</literal>
13767        </entry>
13768        <entry><type>boolean</type></entry>
13769        <entry>does current user have privilege for sequence</entry>
13770       </row>
13771       <row>
13772        <entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
13773                                   <parameter>server</parameter>,
13774                                   <parameter>privilege</parameter>)</literal>
13775        </entry>
13776        <entry><type>boolean</type></entry>
13777        <entry>does user have privilege for foreign server</entry>
13778       </row>
13779       <row>
13780        <entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
13781                                   <parameter>privilege</parameter>)</literal>
13782        </entry>
13783        <entry><type>boolean</type></entry>
13784        <entry>does current user have privilege for foreign server</entry>
13785       </row>
13786       <row>
13787        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
13788                                   <parameter>table</parameter>,
13789                                   <parameter>privilege</parameter>)</literal>
13790        </entry>
13791        <entry><type>boolean</type></entry>
13792        <entry>does user have privilege for table</entry>
13793       </row>
13794       <row>
13795        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
13796                                   <parameter>privilege</parameter>)</literal>
13797        </entry>
13798        <entry><type>boolean</type></entry>
13799        <entry>does current user have privilege for table</entry>
13800       </row>
13801       <row>
13802        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
13803                                   <parameter>tablespace</parameter>,
13804                                   <parameter>privilege</parameter>)</literal>
13805        </entry>
13806        <entry><type>boolean</type></entry>
13807        <entry>does user have privilege for tablespace</entry>
13808       </row>
13809       <row>
13810        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
13811                                   <parameter>privilege</parameter>)</literal>
13812        </entry>
13813        <entry><type>boolean</type></entry>
13814        <entry>does current user have privilege for tablespace</entry>
13815       </row>
13816       <row>
13817        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
13818                                   <parameter>role</parameter>,
13819                                   <parameter>privilege</parameter>)</literal>
13820        </entry>
13821        <entry><type>boolean</type></entry>
13822        <entry>does user have privilege for role</entry>
13823       </row>
13824       <row>
13825        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
13826                                   <parameter>privilege</parameter>)</literal>
13827        </entry>
13828        <entry><type>boolean</type></entry>
13829        <entry>does current user have privilege for role</entry>
13830       </row>
13831      </tbody>
13832     </tgroup>
13833    </table>
13834
13835    <indexterm>
13836     <primary>has_any_column_privilege</primary>
13837    </indexterm>
13838    <indexterm>
13839     <primary>has_column_privilege</primary>
13840    </indexterm>
13841    <indexterm>
13842     <primary>has_database_privilege</primary>
13843    </indexterm>
13844    <indexterm>
13845     <primary>has_function_privilege</primary>
13846    </indexterm>
13847    <indexterm>
13848     <primary>has_foreign_data_wrapper_privilege</primary>
13849    </indexterm>
13850    <indexterm>
13851     <primary>has_language_privilege</primary>
13852    </indexterm>
13853    <indexterm>
13854     <primary>has_schema_privilege</primary>
13855    </indexterm>
13856    <indexterm>
13857     <primary>has_server_privilege</primary>
13858    </indexterm>
13859    <indexterm>
13860     <primary>has_sequence_privilege</primary>
13861    </indexterm>
13862    <indexterm>
13863     <primary>has_table_privilege</primary>
13864    </indexterm>
13865    <indexterm>
13866     <primary>has_tablespace_privilege</primary>
13867    </indexterm>
13868    <indexterm>
13869     <primary>pg_has_role</primary>
13870    </indexterm>
13871
13872    <para>
13873     <function>has_table_privilege</function> checks whether a user
13874     can access a table in a particular way.  The user can be
13875     specified by name, by OID (<literal>pg_authid.oid</literal>),
13876     <literal>public</> to indicate the PUBLIC pseudo-role, or if the argument is
13877     omitted
13878     <function>current_user</function> is assumed.  The table can be specified
13879     by name or by OID.  (Thus, there are actually six variants of
13880     <function>has_table_privilege</function>, which can be distinguished by
13881     the number and types of their arguments.)  When specifying by name,
13882     the name can be schema-qualified if necessary.
13883     The desired access privilege type
13884     is specified by a text string, which must evaluate to one of the
13885     values <literal>SELECT</literal>, <literal>INSERT</literal>,
13886     <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
13887     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.  Optionally,
13888     <literal>WITH GRANT OPTION</> can be added to a privilege type to test
13889     whether the privilege is held with grant option.  Also, multiple privilege
13890     types can be listed separated by commas, in which case the result will
13891     be <literal>true</> if any of the listed privileges is held.
13892     (Case of the privilege string is not significant, and extra whitespace
13893     is allowed between but not within privilege names.)
13894     Some examples:
13895 <programlisting>
13896 SELECT has_table_privilege('myschema.mytable', 'select');
13897 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
13898 </programlisting>
13899    </para>
13900
13901    <para>
13902     <function>has_sequence_privilege</function> checks whether a user
13903     can access a sequence in a particular way.  The possibilities for its
13904     arguments are analogous to <function>has_table_privilege</function>.
13905     The desired access privilege type must evaluate to one of
13906     <literal>USAGE</literal>,
13907     <literal>SELECT</literal>, or
13908     <literal>UPDATE</literal>.
13909    </para>
13910
13911    <para>
13912     <function>has_any_column_privilege</function> checks whether a user can
13913     access any column of a table in a particular way.
13914     Its argument possibilities
13915     are analogous to <function>has_table_privilege</>,
13916     except that the desired access privilege type must evaluate to some
13917     combination of
13918     <literal>SELECT</literal>,
13919     <literal>INSERT</literal>,
13920     <literal>UPDATE</literal>, or
13921     <literal>REFERENCES</literal>.  Note that having any of these privileges
13922     at the table level implicitly grants it for each column of the table,
13923     so <function>has_any_column_privilege</function> will always return
13924     <literal>true</> if <function>has_table_privilege</> does for the same
13925     arguments.  But <function>has_any_column_privilege</> also succeeds if
13926     there is a column-level grant of the privilege for at least one column.
13927    </para>
13928
13929    <para>
13930     <function>has_column_privilege</function> checks whether a user
13931     can access a column in a particular way.
13932     Its argument possibilities
13933     are analogous to <function>has_table_privilege</function>,
13934     with the addition that the column can be specified either by name
13935     or attribute number.
13936     The desired access privilege type must evaluate to some combination of
13937     <literal>SELECT</literal>,
13938     <literal>INSERT</literal>,
13939     <literal>UPDATE</literal>, or
13940     <literal>REFERENCES</literal>.  Note that having any of these privileges
13941     at the table level implicitly grants it for each column of the table.
13942    </para>
13943
13944    <para>
13945     <function>has_database_privilege</function> checks whether a user
13946     can access a database in a particular way.
13947     Its argument possibilities
13948     are analogous to <function>has_table_privilege</function>.
13949     The desired access privilege type must evaluate to some combination of
13950     <literal>CREATE</literal>,
13951     <literal>CONNECT</literal>,
13952     <literal>TEMPORARY</literal>, or
13953     <literal>TEMP</literal> (which is equivalent to
13954     <literal>TEMPORARY</literal>).
13955    </para>
13956
13957    <para>
13958     <function>has_function_privilege</function> checks whether a user
13959     can access a function in a particular way.
13960     Its argument possibilities
13961     are analogous to <function>has_table_privilege</function>.
13962     When specifying a function by a text string rather than by OID,
13963     the allowed input is the same as for the <type>regprocedure</> data type
13964     (see <xref linkend="datatype-oid">).
13965     The desired access privilege type must evaluate to
13966     <literal>EXECUTE</literal>.
13967     An example is:
13968 <programlisting>
13969 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
13970 </programlisting>
13971    </para>
13972
13973    <para>
13974     <function>has_foreign_data_wrapper_privilege</function> checks whether a user
13975     can access a foreign-data wrapper in a particular way.
13976     Its argument possibilities
13977     are analogous to <function>has_table_privilege</function>.
13978     The desired access privilege type must evaluate to
13979     <literal>USAGE</literal>.
13980    </para>
13981
13982    <para>
13983     <function>has_language_privilege</function> checks whether a user
13984     can access a procedural language in a particular way.
13985     Its argument possibilities
13986     are analogous to <function>has_table_privilege</function>.
13987     The desired access privilege type must evaluate to
13988     <literal>USAGE</literal>.
13989    </para>
13990
13991    <para>
13992     <function>has_schema_privilege</function> checks whether a user
13993     can access a schema in a particular way.
13994     Its argument possibilities
13995     are analogous to <function>has_table_privilege</function>.
13996     The desired access privilege type must evaluate to some combination of
13997     <literal>CREATE</literal> or
13998     <literal>USAGE</literal>.
13999    </para>
14000
14001    <para>
14002     <function>has_server_privilege</function> checks whether a user
14003     can access a foreign server in a particular way.
14004     Its argument possibilities
14005     are analogous to <function>has_table_privilege</function>.
14006     The desired access privilege type must evaluate to
14007     <literal>USAGE</literal>.
14008    </para>
14009
14010    <para>
14011     <function>has_tablespace_privilege</function> checks whether a user
14012     can access a tablespace in a particular way.
14013     Its argument possibilities
14014     are analogous to <function>has_table_privilege</function>.
14015     The desired access privilege type must evaluate to
14016     <literal>CREATE</literal>.
14017    </para>
14018
14019    <para>
14020     <function>pg_has_role</function> checks whether a user
14021     can access a role in a particular way.
14022     Its argument possibilities
14023     are analogous to <function>has_table_privilege</function>,
14024     except that <literal>public</> is not allowed as a user name.
14025     The desired access privilege type must evaluate to some combination of
14026     <literal>MEMBER</literal> or
14027     <literal>USAGE</literal>.
14028     <literal>MEMBER</literal> denotes direct or indirect membership in
14029     the role (that is, the right to do <command>SET ROLE</>), while
14030     <literal>USAGE</literal> denotes whether the privileges of the role
14031     are immediately available without doing <command>SET ROLE</>.
14032    </para>
14033
14034   <para>
14035    <xref linkend="functions-info-schema-table"> shows functions that
14036    determine whether a certain object is <firstterm>visible</> in the
14037    current schema search path.
14038    For example, a table is said to be visible if its
14039    containing schema is in the search path and no table of the same
14040    name appears earlier in the search path.  This is equivalent to the
14041    statement that the table can be referenced by name without explicit
14042    schema qualification.  To list the names of all visible tables:
14043 <programlisting>
14044 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
14045 </programlisting>
14046   </para>
14047
14048    <indexterm>
14049     <primary>search path</primary>
14050     <secondary>object visibility</secondary>
14051    </indexterm>
14052
14053    <table id="functions-info-schema-table">
14054     <title>Schema Visibility Inquiry Functions</title>
14055     <tgroup cols="3">
14056      <thead>
14057       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14058      </thead>
14059
14060      <tbody>
14061       <row>
14062        <entry><literal><function>pg_collation_is_visible(<parameter>collation_oid</parameter>)</function></literal>
14063        </entry>
14064        <entry><type>boolean</type></entry>
14065        <entry>is collation visible in search path</entry>
14066       </row>
14067       <row>
14068        <entry><literal><function>pg_conversion_is_visible(<parameter>conversion_oid</parameter>)</function></literal>
14069        </entry>
14070        <entry><type>boolean</type></entry>
14071        <entry>is conversion visible in search path</entry>
14072       </row>
14073       <row>
14074        <entry><literal><function>pg_function_is_visible(<parameter>function_oid</parameter>)</function></literal>
14075        </entry>
14076        <entry><type>boolean</type></entry>
14077        <entry>is function visible in search path</entry>
14078       </row>
14079       <row>
14080        <entry><literal><function>pg_opclass_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
14081        </entry>
14082        <entry><type>boolean</type></entry>
14083        <entry>is operator class visible in search path</entry>
14084       </row>
14085       <row>
14086        <entry><literal><function>pg_operator_is_visible(<parameter>operator_oid</parameter>)</function></literal>
14087        </entry>
14088        <entry><type>boolean</type></entry>
14089        <entry>is operator visible in search path</entry>
14090       </row>
14091       <row>
14092        <entry><literal><function>pg_opfamily_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
14093        </entry>
14094        <entry><type>boolean</type></entry>
14095        <entry>is operator family visible in search path</entry>
14096       </row>
14097       <row>
14098        <entry><literal><function>pg_table_is_visible(<parameter>table_oid</parameter>)</function></literal>
14099        </entry>
14100        <entry><type>boolean</type></entry>
14101        <entry>is table visible in search path</entry>
14102       </row>
14103       <row>
14104        <entry><literal><function>pg_ts_config_is_visible(<parameter>config_oid</parameter>)</function></literal>
14105        </entry>
14106        <entry><type>boolean</type></entry>
14107        <entry>is text search configuration visible in search path</entry>
14108       </row>
14109       <row>
14110        <entry><literal><function>pg_ts_dict_is_visible(<parameter>dict_oid</parameter>)</function></literal>
14111        </entry>
14112        <entry><type>boolean</type></entry>
14113        <entry>is text search dictionary visible in search path</entry>
14114       </row>
14115       <row>
14116        <entry><literal><function>pg_ts_parser_is_visible(<parameter>parser_oid</parameter>)</function></literal>
14117        </entry>
14118        <entry><type>boolean</type></entry>
14119        <entry>is text search parser visible in search path</entry>
14120       </row>
14121       <row>
14122        <entry><literal><function>pg_ts_template_is_visible(<parameter>template_oid</parameter>)</function></literal>
14123        </entry>
14124        <entry><type>boolean</type></entry>
14125        <entry>is text search template visible in search path</entry>
14126       </row>
14127       <row>
14128        <entry><literal><function>pg_type_is_visible(<parameter>type_oid</parameter>)</function></literal>
14129        </entry>
14130        <entry><type>boolean</type></entry>
14131        <entry>is type (or domain) visible in search path</entry>
14132       </row>
14133      </tbody>
14134     </tgroup>
14135    </table>
14136
14137    <indexterm>
14138     <primary>pg_collation_is_visible</primary>
14139    </indexterm>
14140    <indexterm>
14141     <primary>pg_conversion_is_visible</primary>
14142    </indexterm>
14143    <indexterm>
14144     <primary>pg_function_is_visible</primary>
14145    </indexterm>
14146    <indexterm>
14147     <primary>pg_opclass_is_visible</primary>
14148    </indexterm>
14149    <indexterm>
14150     <primary>pg_operator_is_visible</primary>
14151    </indexterm>
14152    <indexterm>
14153     <primary>pg_opfamily_is_visible</primary>
14154    </indexterm>
14155    <indexterm>
14156     <primary>pg_table_is_visible</primary>
14157    </indexterm>
14158    <indexterm>
14159     <primary>pg_ts_config_is_visible</primary>
14160    </indexterm>
14161    <indexterm>
14162     <primary>pg_ts_dict_is_visible</primary>
14163    </indexterm>
14164    <indexterm>
14165     <primary>pg_ts_parser_is_visible</primary>
14166    </indexterm>
14167    <indexterm>
14168     <primary>pg_ts_template_is_visible</primary>
14169    </indexterm>
14170    <indexterm>
14171     <primary>pg_type_is_visible</primary>
14172    </indexterm>
14173
14174    <para>
14175     Each function performs the visibility check for one type of database
14176     object.  Note that <function>pg_table_is_visible</function> can also be used
14177     with views, indexes and sequences; <function>pg_type_is_visible</function>
14178     can also be used with domains. For functions and operators, an object in
14179     the search path is visible if there is no object of the same name
14180     <emphasis>and argument data type(s)</> earlier in the path.  For operator
14181     classes, both name and associated index access method are considered.
14182    </para>
14183
14184    <para>
14185     All these functions require object OIDs to identify the object to be
14186     checked.  If you want to test an object by name, it is convenient to use
14187     the OID alias types (<type>regclass</>, <type>regtype</>,
14188     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
14189     or <type>regdictionary</>),
14190     for example:
14191 <programlisting>
14192 SELECT pg_type_is_visible('myschema.widget'::regtype);
14193 </programlisting>
14194     Note that it would not make much sense to test a non-schema-qualified
14195     type name in this way &mdash; if the name can be recognized at all, it must be visible.
14196    </para>
14197
14198    <indexterm>
14199     <primary>format_type</primary>
14200    </indexterm>
14201
14202    <indexterm>
14203     <primary>pg_describe_object</primary>
14204    </indexterm>
14205
14206    <indexterm>
14207     <primary>pg_identify_object</primary>
14208    </indexterm>
14209
14210    <indexterm>
14211     <primary>pg_get_constraintdef</primary>
14212    </indexterm>
14213
14214    <indexterm>
14215     <primary>pg_get_expr</primary>
14216    </indexterm>
14217
14218    <indexterm>
14219     <primary>pg_get_functiondef</primary>
14220    </indexterm>
14221
14222    <indexterm>
14223     <primary>pg_get_function_arguments</primary>
14224    </indexterm>
14225
14226    <indexterm>
14227     <primary>pg_get_function_identity_arguments</primary>
14228    </indexterm>
14229
14230    <indexterm>
14231     <primary>pg_get_function_result</primary>
14232    </indexterm>
14233
14234    <indexterm>
14235     <primary>pg_get_indexdef</primary>
14236    </indexterm>
14237
14238    <indexterm>
14239     <primary>pg_get_keywords</primary>
14240    </indexterm>
14241
14242    <indexterm>
14243     <primary>pg_get_ruledef</primary>
14244    </indexterm>
14245
14246    <indexterm>
14247     <primary>pg_get_serial_sequence</primary>
14248    </indexterm>
14249
14250    <indexterm>
14251     <primary>pg_get_triggerdef</primary>
14252    </indexterm>
14253
14254    <indexterm>
14255     <primary>pg_get_userbyid</primary>
14256    </indexterm>
14257
14258    <indexterm>
14259     <primary>pg_get_viewdef</primary>
14260    </indexterm>
14261
14262    <indexterm>
14263     <primary>pg_options_to_table</primary>
14264    </indexterm>
14265
14266    <indexterm>
14267     <primary>pg_tablespace_databases</primary>
14268    </indexterm>
14269
14270    <indexterm>
14271     <primary>pg_tablespace_location</primary>
14272    </indexterm>
14273
14274    <indexterm>
14275     <primary>pg_typeof</primary>
14276    </indexterm>
14277
14278    <indexterm>
14279     <primary>collation for</primary>
14280    </indexterm>
14281
14282   <para>
14283    <xref linkend="functions-info-catalog-table"> lists functions that
14284    extract information from the system catalogs.
14285   </para>
14286
14287    <table id="functions-info-catalog-table">
14288     <title>System Catalog Information Functions</title>
14289     <tgroup cols="3">
14290      <thead>
14291       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14292      </thead>
14293
14294      <tbody>
14295       <row>
14296        <entry><literal><function>format_type(<parameter>type_oid</parameter>, <parameter>typemod</>)</function></literal></entry>
14297        <entry><type>text</type></entry>
14298        <entry>get SQL name of a data type</entry>
14299       </row>
14300       <row>
14301        <entry><literal><function>pg_describe_object(<parameter>catalog_id</parameter>, <parameter>object_id</parameter>, <parameter>object_sub_id</parameter>)</function></literal></entry>
14302        <entry><type>text</type></entry>
14303        <entry>get description of a database object</entry>
14304       </row>
14305       <row>
14306        <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>
14307        <entry><parameter>type</> <type>text</>, <parameter>schema</> <type>text</>, <parameter>name</> <type>text</>, <parameter>identity</> <type>text</></entry>
14308        <entry>get identity of a database object</entry>
14309       </row>
14310       <row>
14311        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>)</function></literal></entry>
14312        <entry><type>text</type></entry>
14313        <entry>get definition of a constraint</entry>
14314       </row>
14315       <row>
14316        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
14317        <entry><type>text</type></entry>
14318        <entry>get definition of a constraint</entry>
14319       </row>
14320       <row>
14321        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>)</function></literal></entry>
14322        <entry><type>text</type></entry>
14323        <entry>decompile internal form of an expression, assuming that any Vars
14324        in it refer to the relation indicated by the second parameter</entry>
14325       </row>
14326       <row>
14327        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</function></literal></entry>
14328        <entry><type>text</type></entry>
14329        <entry>decompile internal form of an expression, assuming that any Vars
14330        in it refer to the relation indicated by the second parameter</entry>
14331       </row>
14332       <row>
14333        <entry><literal><function>pg_get_functiondef(<parameter>func_oid</parameter>)</function></literal></entry>
14334        <entry><type>text</type></entry>
14335        <entry>get definition of a function</entry>
14336       </row>
14337       <row>
14338        <entry><literal><function>pg_get_function_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
14339        <entry><type>text</type></entry>
14340        <entry>get argument list of function's definition (with default values)</entry>
14341       </row>
14342       <row>
14343        <entry><literal><function>pg_get_function_identity_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
14344        <entry><type>text</type></entry>
14345        <entry>get argument list to identify a function (without default values)</entry>
14346       </row>
14347       <row>
14348        <entry><literal><function>pg_get_function_result(<parameter>func_oid</parameter>)</function></literal></entry>
14349        <entry><type>text</type></entry>
14350        <entry>get <literal>RETURNS</> clause for function</entry>
14351       </row>
14352       <row>
14353        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>)</function></literal></entry>
14354        <entry><type>text</type></entry>
14355        <entry>get <command>CREATE INDEX</> command for index</entry>
14356       </row>
14357       <row>
14358        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</function></literal></entry>
14359        <entry><type>text</type></entry>
14360        <entry>get <command>CREATE INDEX</> command for index,
14361        or definition of just one index column when
14362        <parameter>column_no</> is not zero</entry>
14363       </row>
14364       <row>
14365        <entry><literal><function>pg_get_keywords()</function></literal></entry>
14366        <entry><type>setof record</type></entry>
14367        <entry>get list of SQL keywords and their categories</entry>
14368       </row>
14369       <row>
14370        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>)</function></literal></entry>
14371        <entry><type>text</type></entry>
14372        <entry>get <command>CREATE RULE</> command for rule</entry>
14373       </row>
14374       <row>
14375        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
14376        <entry><type>text</type></entry>
14377        <entry>get <command>CREATE RULE</> command for rule</entry>
14378       </row>
14379       <row>
14380        <entry><literal><function>pg_get_serial_sequence(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</function></literal></entry>
14381        <entry><type>text</type></entry>
14382        <entry>get name of the sequence that a <type>serial</type>, <type>smallserial</type> or <type>bigserial</type> column
14383        uses</entry>
14384       </row>
14385       <row>
14386        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
14387        <entry><type>text</type></entry>
14388        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
14389       </row>
14390       <row>
14391        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>, <parameter>pretty_bool</>)</entry>
14392        <entry><type>text</type></entry>
14393        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
14394       </row>
14395       <row>
14396        <entry><literal><function>pg_get_userbyid(<parameter>role_oid</parameter>)</function></literal></entry>
14397        <entry><type>name</type></entry>
14398        <entry>get role name with given OID</entry>
14399       </row>
14400       <row>
14401        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>)</function></literal></entry>
14402        <entry><type>text</type></entry>
14403        <entry>get underlying <command>SELECT</command> command for view or materialized view (<emphasis>deprecated</emphasis>)</entry>
14404       </row>
14405       <row>
14406        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
14407        <entry><type>text</type></entry>
14408        <entry>get underlying <command>SELECT</command> command for view or materialized view (<emphasis>deprecated</emphasis>)</entry>
14409       </row>
14410       <row>
14411        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>)</function></literal></entry>
14412        <entry><type>text</type></entry>
14413        <entry>get underlying <command>SELECT</command> command for view or materialized view</entry>
14414       </row>
14415       <row>
14416        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
14417        <entry><type>text</type></entry>
14418        <entry>get underlying <command>SELECT</command> command for view or materialized view</entry>
14419       </row>
14420       <row>
14421        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>wrap_column_int</>)</function></literal></entry>
14422        <entry><type>text</type></entry>
14423        <entry>get underlying <command>SELECT</command> command for view or
14424               materialized view; lines with fields are wrapped to specified
14425               number of columns, pretty-printing is implied</entry>
14426       </row>
14427       <row>
14428        <entry><literal><function>pg_options_to_table(<parameter>reloptions</parameter>)</function></literal></entry>
14429        <entry><type>setof record</type></entry>
14430        <entry>get the set of storage option name/value pairs</entry>
14431       </row>
14432       <row>
14433        <entry><literal><function>pg_tablespace_databases(<parameter>tablespace_oid</parameter>)</function></literal></entry>
14434        <entry><type>setof oid</type></entry>
14435        <entry>get the set of database OIDs that have objects in the tablespace</entry>
14436       </row>
14437       <row>
14438        <entry><literal><function>pg_tablespace_location(<parameter>tablespace_oid</parameter>)</function></literal></entry>
14439        <entry><type>text</type></entry>
14440        <entry>get the path in the file system that this tablespace is located in</entry>
14441       </row>
14442       <row>
14443        <entry><literal><function>pg_typeof(<parameter>any</parameter>)</function></literal></entry>
14444        <entry><type>regtype</type></entry>
14445        <entry>get the data type of any value</entry>
14446       </row>
14447       <row>
14448        <entry><literal><function>collation for (<parameter>any</parameter>)</function></literal></entry>
14449        <entry><type>text</type></entry>
14450        <entry>get the collation of the argument</entry>
14451       </row>
14452      </tbody>
14453     </tgroup>
14454    </table>
14455
14456   <para>
14457    <function>format_type</function> returns the SQL name of a data type that
14458    is identified by its type OID and possibly a type modifier.  Pass NULL
14459    for the type modifier if no specific modifier is known.
14460   </para>
14461
14462   <para>
14463    <function>pg_get_keywords</function> returns a set of records describing
14464    the SQL keywords recognized by the server. The <structfield>word</> column
14465    contains the keyword.  The <structfield>catcode</> column contains a
14466    category code: <literal>U</> for unreserved, <literal>C</> for column name,
14467    <literal>T</> for type or function name, or <literal>R</> for reserved.
14468    The <structfield>catdesc</> column contains a possibly-localized string
14469    describing the category.
14470   </para>
14471
14472   <para>
14473    <function>pg_get_constraintdef</function>,
14474    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
14475    and <function>pg_get_triggerdef</function>, respectively reconstruct the
14476    creating command for a constraint, index, rule, or trigger. (Note that this
14477    is a decompiled reconstruction, not the original text of the command.)
14478    <function>pg_get_expr</function> decompiles the internal form of an
14479    individual expression, such as the default value for a column.  It can be
14480    useful when examining the contents of system catalogs.  If the expression
14481    might contain Vars, specify the OID of the relation they refer to as the
14482    second parameter; if no Vars are expected, zero is sufficient.
14483    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
14484    query that defines a view. Most of these functions come in two variants,
14485    one of which can optionally <quote>pretty-print</> the result.  The
14486    pretty-printed format is more readable, but the default format is more
14487    likely to be interpreted the same way by future versions of
14488    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
14489    purposes.  Passing <literal>false</> for the pretty-print parameter yields
14490    the same result as the variant that does not have the parameter at all.
14491   </para>
14492
14493   <para>
14494    <function>pg_get_functiondef</> returns a complete
14495    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
14496    <function>pg_get_function_arguments</function> returns the argument list
14497    of a function, in the form it would need to appear in within
14498    <command>CREATE FUNCTION</>.
14499    <function>pg_get_function_result</function> similarly returns the
14500    appropriate <literal>RETURNS</> clause for the function.
14501    <function>pg_get_function_identity_arguments</function> returns the
14502    argument list necessary to identify a function, in the form it
14503    would need to appear in within <command>ALTER FUNCTION</>, for
14504    instance.  This form omits default values.
14505   </para>
14506
14507   <para>
14508    <function>pg_get_serial_sequence</function> returns the name of the
14509    sequence associated with a column, or NULL if no sequence is associated
14510    with the column.  The first input parameter is a table name with
14511    optional schema, and the second parameter is a column name.  Because
14512    the first parameter is potentially a schema and table, it is not treated
14513    as a double-quoted identifier, meaning it is lower cased by default,
14514    while the second parameter, being just a column name, is treated as
14515    double-quoted and has its case preserved.  The function returns a value
14516    suitably formatted for passing to sequence functions (see <xref
14517    linkend="functions-sequence">).  This association can be modified or
14518    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
14519    probably should have been called
14520    <function>pg_get_owned_sequence</function>; its current name reflects the fact
14521    that it's typically used with <type>serial</> or <type>bigserial</>
14522    columns.)
14523   </para>
14524
14525   <para>
14526    <function>pg_get_userbyid</function> extracts a role's name given
14527    its OID.
14528   </para>
14529
14530   <para>
14531    <function>pg_options_to_table</function> returns the set of storage
14532    option name/value pairs
14533    (<literal>option_name</>/<literal>option_value</>) when passed
14534    <structname>pg_class</>.<structfield>reloptions</> or
14535    <structname>pg_attribute</>.<structfield>attoptions</>.
14536   </para>
14537
14538   <para>
14539    <function>pg_tablespace_databases</function> allows a tablespace to be
14540    examined. It returns the set of OIDs of databases that have objects stored
14541    in the tablespace. If this function returns any rows, the tablespace is not
14542    empty and cannot be dropped. To display the specific objects populating the
14543    tablespace, you will need to connect to the databases identified by
14544    <function>pg_tablespace_databases</function> and query their
14545    <structname>pg_class</> catalogs.
14546   </para>
14547
14548   <para>
14549    <function>pg_describe_object</function> returns a textual description of a database
14550    object specified by catalog OID, object OID and a (possibly zero) sub-object ID.
14551    This description is intended to be human-readable, and might be translated,
14552    depending on server configuration.
14553    This is useful to determine the identity of an object as stored in the
14554    <structname>pg_depend</structname> catalog.
14555   </para>
14556
14557   <para>
14558    <function>pg_identify_object</function> returns a row containing enough information
14559    to uniquely identify the database object specified by catalog OID, object OID and a
14560    (possibly zero) sub-object ID.  This information is intended to be machine-readable,
14561    and is never translated.
14562    <parameter>type</> identifies the type of database object;
14563    <parameter>schema</> is the schema name that the object belongs in, or
14564    <literal>NULL</> for object types that do not belong to schemas;
14565    <parameter>name</> is the name of the object, quoted if necessary, only
14566    present if it can be used (alongside schema name, if pertinent) as an unique
14567    identifier of the object, otherwise <literal>NULL</>;
14568    <parameter>identity</> is the complete object identity, with the precise format
14569    depending on object type, and each part within the format being
14570    schema-qualified and quoted as necessary.
14571   </para>
14572
14573   <para>
14574    <function>pg_typeof</function> returns the OID of the data type of the
14575    value that is passed to it.  This can be helpful for troubleshooting or
14576    dynamically constructing SQL queries.  The function is declared as
14577    returning <type>regtype</>, which is an OID alias type (see
14578    <xref linkend="datatype-oid">); this means that it is the same as an
14579    OID for comparison purposes but displays as a type name.  For example:
14580 <programlisting>
14581 SELECT pg_typeof(33);
14582
14583  pg_typeof 
14584 -----------
14585  integer
14586 (1 row)
14587
14588 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
14589  typlen 
14590 --------
14591       4
14592 (1 row)
14593 </programlisting>
14594   </para>
14595
14596   <para>
14597    The expression <literal>collation for</literal> returns the collation of the
14598    value that is passed to it.  Example:
14599 <programlisting>
14600 SELECT collation for (description) FROM pg_description LIMIT 1;
14601  pg_collation_for 
14602 ------------------
14603  "default"
14604 (1 row)
14605
14606 SELECT collation for ('foo' COLLATE "de_DE");
14607  pg_collation_for 
14608 ------------------
14609  "de_DE"
14610 (1 row)
14611 </programlisting>
14612   The value might be quoted and schema-qualified.  If no collation is derived
14613   for the argument expression, then a null value is returned.  If the argument
14614   is not of a collatable data type, then an error is raised.
14615   </para>
14616
14617    <indexterm>
14618     <primary>col_description</primary>
14619    </indexterm>
14620
14621    <indexterm>
14622     <primary>obj_description</primary>
14623    </indexterm>
14624
14625    <indexterm>
14626     <primary>shobj_description</primary>
14627    </indexterm>
14628
14629    <indexterm>
14630     <primary>comment</primary>
14631     <secondary sortas="database objects">about database objects</secondary>
14632    </indexterm>
14633
14634    <para>
14635     The functions shown in <xref linkend="functions-info-comment-table">
14636     extract comments previously stored with the <xref linkend="sql-comment">
14637     command.  A null value is returned if no
14638     comment could be found for the specified parameters.
14639    </para>
14640
14641    <table id="functions-info-comment-table">
14642     <title>Comment Information Functions</title>
14643     <tgroup cols="3">
14644      <thead>
14645       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14646      </thead>
14647
14648      <tbody>
14649       <row>
14650        <entry><literal><function>col_description(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</function></literal></entry>
14651        <entry><type>text</type></entry>
14652        <entry>get comment for a table column</entry>
14653       </row>
14654       <row>
14655        <entry><literal><function>obj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
14656        <entry><type>text</type></entry>
14657        <entry>get comment for a database object</entry>
14658       </row>
14659       <row>
14660        <entry><literal><function>obj_description(<parameter>object_oid</parameter>)</function></literal></entry>
14661        <entry><type>text</type></entry>
14662        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
14663       </row>
14664       <row>
14665        <entry><literal><function>shobj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
14666        <entry><type>text</type></entry>
14667        <entry>get comment for a shared database object</entry>
14668       </row>
14669      </tbody>
14670     </tgroup>
14671    </table>
14672
14673    <para>
14674     <function>col_description</function> returns the comment for a table
14675     column, which is specified by the OID of its table and its column number.
14676     (<function>obj_description</function> cannot be used for table columns
14677     since columns do not have OIDs of their own.)
14678    </para>
14679
14680    <para>
14681     The two-parameter form of <function>obj_description</function> returns the
14682     comment for a database object specified by its OID and the name of the
14683     containing system catalog.  For example,
14684     <literal>obj_description(123456,'pg_class')</literal>
14685     would retrieve the comment for the table with OID 123456.
14686     The one-parameter form of <function>obj_description</function> requires only
14687     the object OID.  It is deprecated since there is no guarantee that
14688     OIDs are unique across different system catalogs; therefore, the wrong
14689     comment might be returned.
14690    </para>
14691
14692    <para>
14693     <function>shobj_description</function> is used just like
14694     <function>obj_description</function> except it is used for retrieving
14695     comments on shared objects.  Some system catalogs are global to all
14696     databases within each cluster, and the descriptions for objects in them
14697     are stored globally as well.
14698    </para>
14699
14700    <indexterm>
14701     <primary>txid_current</primary>
14702    </indexterm>
14703
14704    <indexterm>
14705     <primary>txid_current_snapshot</primary>
14706    </indexterm>
14707
14708    <indexterm>
14709     <primary>txid_snapshot_xip</primary>
14710    </indexterm>
14711
14712    <indexterm>
14713     <primary>txid_snapshot_xmax</primary>
14714    </indexterm>
14715
14716    <indexterm>
14717     <primary>txid_snapshot_xmin</primary>
14718    </indexterm>
14719
14720    <indexterm>
14721     <primary>txid_visible_in_snapshot</primary>
14722    </indexterm>
14723
14724    <para>
14725     The functions shown in <xref linkend="functions-txid-snapshot">
14726     provide server transaction information in an exportable form.  The main
14727     use of these functions is to determine which transactions were committed
14728     between two snapshots.
14729    </para>
14730
14731    <table id="functions-txid-snapshot">
14732     <title>Transaction IDs and Snapshots</title>
14733     <tgroup cols="3">
14734      <thead>
14735       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14736      </thead>
14737
14738      <tbody>
14739       <row>
14740        <entry><literal><function>txid_current()</function></literal></entry>
14741        <entry><type>bigint</type></entry>
14742        <entry>get current transaction ID</entry>
14743       </row>
14744       <row>
14745        <entry><literal><function>txid_current_snapshot()</function></literal></entry>
14746        <entry><type>txid_snapshot</type></entry>
14747        <entry>get current snapshot</entry>
14748       </row>
14749       <row>
14750        <entry><literal><function>txid_snapshot_xip(<parameter>txid_snapshot</parameter>)</function></literal></entry>
14751        <entry><type>setof bigint</type></entry>
14752        <entry>get in-progress transaction IDs in snapshot</entry>
14753       </row>
14754       <row>
14755        <entry><literal><function>txid_snapshot_xmax(<parameter>txid_snapshot</parameter>)</function></literal></entry>
14756        <entry><type>bigint</type></entry>
14757        <entry>get <literal>xmax</literal> of snapshot</entry>
14758       </row>
14759       <row>
14760        <entry><literal><function>txid_snapshot_xmin(<parameter>txid_snapshot</parameter>)</function></literal></entry>
14761        <entry><type>bigint</type></entry>
14762        <entry>get <literal>xmin</literal> of snapshot</entry>
14763       </row>
14764       <row>
14765        <entry><literal><function>txid_visible_in_snapshot(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</function></literal></entry>
14766        <entry><type>boolean</type></entry>
14767        <entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
14768       </row>
14769      </tbody>
14770     </tgroup>
14771    </table>
14772
14773    <para>
14774     The internal transaction ID type (<type>xid</>) is 32 bits wide and
14775     wraps around every 4 billion transactions.  However, these functions
14776     export a 64-bit format that is extended with an <quote>epoch</> counter
14777     so it will not wrap around during the life of an installation.
14778     The data type used by these functions, <type>txid_snapshot</type>,
14779     stores information about transaction ID
14780     visibility at a particular moment in time.  Its components are
14781     described in <xref linkend="functions-txid-snapshot-parts">.
14782    </para>
14783
14784    <table id="functions-txid-snapshot-parts">
14785     <title>Snapshot Components</title>
14786     <tgroup cols="2">
14787      <thead>
14788       <row>
14789        <entry>Name</entry>
14790        <entry>Description</entry>
14791       </row>
14792      </thead>
14793
14794      <tbody>
14795
14796       <row>
14797        <entry><type>xmin</type></entry>
14798        <entry>
14799          Earliest transaction ID (txid) that is still active.  All earlier
14800          transactions will either be committed and visible, or rolled
14801          back and dead.
14802        </entry>
14803       </row>
14804
14805       <row>
14806        <entry><type>xmax</type></entry>
14807        <entry>
14808         First as-yet-unassigned txid.  All txids greater than or equal to this
14809         are not yet started as of the time of the snapshot, and thus invisible.
14810        </entry>
14811       </row>
14812
14813       <row>
14814        <entry><type>xip_list</type></entry>
14815        <entry>
14816         Active txids at the time of the snapshot.  The list
14817         includes only those active txids between <literal>xmin</>
14818         and <literal>xmax</>; there might be active txids higher
14819         than <literal>xmax</>.  A txid that is <literal>xmin &lt;= txid &lt;
14820         xmax</literal> and not in this list was already completed
14821         at the time of the snapshot, and thus either visible or
14822         dead according to its commit status.  The list does not
14823         include txids of subtransactions.
14824        </entry>
14825       </row>
14826
14827      </tbody>
14828     </tgroup>
14829    </table>
14830
14831    <para>
14832     <type>txid_snapshot</>'s textual representation is
14833     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
14834     For example <literal>10:20:10,14,15</literal> means
14835     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
14836    </para>
14837   </sect1>
14838
14839   <sect1 id="functions-admin">
14840    <title>System Administration Functions</title>
14841
14842    <para>
14843     The functions described in this section are used to control and
14844     monitor a <productname>PostgreSQL</> installation.
14845    </para>
14846
14847   <sect2 id="functions-admin-set">
14848    <title>Configuration Settings Functions</title>
14849
14850    <para>
14851     <xref linkend="functions-admin-set-table"> shows the functions
14852     available to query and alter run-time configuration parameters.
14853    </para>
14854
14855    <table id="functions-admin-set-table">
14856     <title>Configuration Settings Functions</title>
14857     <tgroup cols="3">
14858      <thead>
14859       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14860      </thead>
14861
14862      <tbody>
14863       <row>
14864        <entry>
14865         <indexterm>
14866          <primary>current_setting</primary>
14867         </indexterm>
14868         <literal><function>current_setting(<parameter>setting_name</parameter>)</function></literal>
14869        </entry>
14870        <entry><type>text</type></entry>
14871        <entry>get current value of setting</entry>
14872       </row>
14873       <row>
14874        <entry>
14875         <indexterm>
14876          <primary>set_config</primary>
14877         </indexterm>
14878         <literal><function>set_config(<parameter>setting_name</parameter>,
14879                              <parameter>new_value</parameter>,
14880                              <parameter>is_local</parameter>)</function></literal>
14881        </entry>
14882        <entry><type>text</type></entry>
14883        <entry>set parameter and return new value</entry>
14884       </row>
14885      </tbody>
14886     </tgroup>
14887    </table>
14888
14889    <indexterm>
14890     <primary>SET</primary>
14891    </indexterm>
14892
14893    <indexterm>
14894     <primary>SHOW</primary>
14895    </indexterm>
14896
14897    <indexterm>
14898     <primary>configuration</primary>
14899     <secondary sortas="server">of the server</secondary>
14900     <tertiary>functions</tertiary>
14901    </indexterm>
14902
14903    <para>
14904     The function <function>current_setting</function> yields the
14905     current value of the setting <parameter>setting_name</parameter>.
14906     It corresponds to the <acronym>SQL</acronym> command
14907     <command>SHOW</command>.  An example:
14908 <programlisting>
14909 SELECT current_setting('datestyle');
14910
14911  current_setting
14912 -----------------
14913  ISO, MDY
14914 (1 row)
14915 </programlisting>
14916    </para>
14917
14918    <para>
14919     <function>set_config</function> sets the parameter
14920     <parameter>setting_name</parameter> to
14921     <parameter>new_value</parameter>.  If
14922     <parameter>is_local</parameter> is <literal>true</literal>, the
14923     new value will only apply to the current transaction. If you want
14924     the new value to apply for the current session, use
14925     <literal>false</literal> instead. The function corresponds to the
14926     SQL command <command>SET</command>. An example:
14927 <programlisting>
14928 SELECT set_config('log_statement_stats', 'off', false);
14929
14930  set_config
14931 ------------
14932  off
14933 (1 row)
14934 </programlisting>
14935    </para>
14936
14937   </sect2>
14938
14939   <sect2 id="functions-admin-signal">
14940    <title>Server Signaling Functions</title>
14941
14942    <indexterm>
14943     <primary>pg_cancel_backend</primary>
14944    </indexterm>
14945    <indexterm>
14946     <primary>pg_reload_conf</primary>
14947    </indexterm>
14948    <indexterm>
14949     <primary>pg_rotate_logfile</primary>
14950    </indexterm>
14951    <indexterm>
14952     <primary>pg_terminate_backend</primary>
14953    </indexterm>
14954
14955    <indexterm>
14956     <primary>signal</primary>
14957     <secondary sortas="backend">backend processes</secondary>
14958    </indexterm>
14959
14960    <para>
14961     The functions shown in <xref
14962     linkend="functions-admin-signal-table"> send control signals to
14963     other server processes.  Use of these functions is usually restricted
14964     to superusers, with noted exceptions.
14965    </para>
14966
14967    <table id="functions-admin-signal-table">
14968     <title>Server Signaling Functions</title>
14969     <tgroup cols="3">
14970      <thead>
14971       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14972       </row>
14973      </thead>
14974
14975      <tbody>
14976       <row>
14977        <entry>
14978         <literal><function>pg_cancel_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
14979         </entry>
14980        <entry><type>boolean</type></entry>
14981        <entry>Cancel a backend's current query.  You can execute this against
14982         another backend that has exactly the same role as the user calling the
14983         function.  In all other cases, you must be a superuser.
14984         </entry>
14985       </row>
14986       <row>
14987        <entry>
14988         <literal><function>pg_reload_conf()</function></literal>
14989         </entry>
14990        <entry><type>boolean</type></entry>
14991        <entry>Cause server processes to reload their configuration files</entry>
14992       </row>
14993       <row>
14994        <entry>
14995         <literal><function>pg_rotate_logfile()</function></literal>
14996         </entry>
14997        <entry><type>boolean</type></entry>
14998        <entry>Rotate server's log file</entry>
14999       </row>
15000       <row>
15001        <entry>
15002         <literal><function>pg_terminate_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
15003         </entry>
15004        <entry><type>boolean</type></entry>
15005        <entry>Terminate a backend.  You can execute this against
15006         another backend that has exactly the same role as the user
15007         calling the function.  In all other cases, you must be a
15008         superuser.
15009        </entry>
15010       </row>
15011      </tbody>
15012     </tgroup>
15013    </table>
15014
15015    <para>
15016     Each of these functions returns <literal>true</literal> if
15017     successful and <literal>false</literal> otherwise.
15018    </para>
15019
15020    <para>
15021     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
15022     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
15023     respectively) to backend processes identified by process ID.
15024     The process ID of an active backend can be found from
15025     the <structfield>pid</structfield> column of the
15026     <structname>pg_stat_activity</structname> view, or by listing the
15027     <command>postgres</command> processes on the server (using
15028     <application>ps</> on Unix or the <application>Task
15029     Manager</> on <productname>Windows</>).
15030     The role of an active backend can be found from the
15031     <structfield>usename</structfield> column of the
15032     <structname>pg_stat_activity</structname> view.
15033    </para>
15034
15035    <para>
15036     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
15037     to the server, causing configuration files
15038     to be reloaded by all server processes.
15039    </para>
15040
15041    <para>
15042     <function>pg_rotate_logfile</> signals the log-file manager to switch
15043     to a new output file immediately.  This works only when the built-in
15044     log collector is running, since otherwise there is no log-file manager
15045     subprocess.
15046    </para>
15047
15048   </sect2>
15049
15050   <sect2 id="functions-admin-backup">
15051    <title>Backup Control Functions</title>
15052
15053    <indexterm>
15054     <primary>backup</primary>
15055    </indexterm>
15056    <indexterm>
15057     <primary>pg_create_restore_point</primary>
15058    </indexterm>
15059    <indexterm>
15060     <primary>pg_current_xlog_insert_location</primary>
15061    </indexterm>
15062    <indexterm>
15063     <primary>pg_current_xlog_location</primary>
15064    </indexterm>
15065    <indexterm>
15066     <primary>pg_start_backup</primary>
15067    </indexterm>
15068    <indexterm>
15069     <primary>pg_stop_backup</primary>
15070    </indexterm>
15071    <indexterm>
15072     <primary>pg_is_in_backup</primary>
15073    </indexterm>
15074    <indexterm>
15075     <primary>pg_backup_start_time</primary>
15076    </indexterm>
15077    <indexterm>
15078     <primary>pg_switch_xlog</primary>
15079    </indexterm>
15080    <indexterm>
15081     <primary>pg_xlogfile_name</primary>
15082    </indexterm>
15083    <indexterm>
15084     <primary>pg_xlogfile_name_offset</primary>
15085    </indexterm>
15086    <indexterm>
15087     <primary>pg_xlog_location_diff</primary>
15088    </indexterm>
15089
15090    <para>
15091     The functions shown in <xref
15092     linkend="functions-admin-backup-table"> assist in making on-line backups.
15093     These functions cannot be executed during recovery (except
15094     <function>pg_is_in_backup</function>, <function>pg_backup_start_time</function>
15095     and <function>pg_xlog_location_diff</function>).
15096    </para>
15097
15098    <table id="functions-admin-backup-table">
15099     <title>Backup Control Functions</title>
15100     <tgroup cols="3">
15101      <thead>
15102       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15103       </row>
15104      </thead>
15105
15106      <tbody>
15107       <row>
15108        <entry>
15109         <literal><function>pg_create_restore_point(<parameter>name</> <type>text</>)</function></literal>
15110         </entry>
15111        <entry><type>text</type></entry>
15112        <entry>Create a named point for performing restore (restricted to superusers)</entry>
15113       </row>
15114       <row>
15115        <entry>
15116         <literal><function>pg_current_xlog_insert_location()</function></literal>
15117         </entry>
15118        <entry><type>text</type></entry>
15119        <entry>Get current transaction log insert location</entry>
15120       </row>
15121       <row>
15122        <entry>
15123         <literal><function>pg_current_xlog_location()</function></literal>
15124         </entry>
15125        <entry><type>text</type></entry>
15126        <entry>Get current transaction log write location</entry>
15127       </row>
15128       <row>
15129        <entry>
15130         <literal><function>pg_start_backup(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> </optional>)</function></literal>
15131         </entry>
15132        <entry><type>text</type></entry>
15133        <entry>Prepare for performing on-line backup (restricted to superusers or replication roles)</entry>
15134       </row>
15135       <row>
15136        <entry>
15137         <literal><function>pg_stop_backup()</function></literal>
15138         </entry>
15139        <entry><type>text</type></entry>
15140        <entry>Finish performing on-line backup (restricted to superusers or replication roles)</entry>
15141       </row>
15142       <row>
15143        <entry>
15144         <literal><function>pg_is_in_backup()</function></literal>
15145         </entry>
15146        <entry><type>bool</type></entry>
15147        <entry>True if an on-line exclusive backup is still in progress.</entry>
15148       </row>
15149       <row>
15150        <entry>
15151         <literal><function>pg_backup_start_time()</function></literal>
15152         </entry>
15153        <entry><type>timestamp with time zone</type></entry>
15154        <entry>Get start time of an on-line exclusive backup in progress.</entry>
15155       </row>
15156       <row>
15157        <entry>
15158         <literal><function>pg_switch_xlog()</function></literal>
15159         </entry>
15160        <entry><type>text</type></entry>
15161        <entry>Force switch to a new transaction log file (restricted to superusers)</entry>
15162       </row>
15163       <row>
15164        <entry>
15165         <literal><function>pg_xlogfile_name(<parameter>location</> <type>text</>)</function></literal>
15166         </entry>
15167        <entry><type>text</type></entry>
15168        <entry>Convert transaction log location string to file name</entry>
15169       </row>
15170       <row>
15171        <entry>
15172         <literal><function>pg_xlogfile_name_offset(<parameter>location</> <type>text</>)</function></literal>
15173         </entry>
15174        <entry><type>text</>, <type>integer</></entry>
15175        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
15176       </row>
15177       <row>
15178        <entry>
15179         <literal><function>pg_xlog_location_diff(<parameter>location</> <type>text</>, <parameter>location</> <type>text</>)</function></literal>
15180        </entry>
15181        <entry><type>numeric</></entry>
15182        <entry>Calculate the difference between two transaction log locations</entry>
15183       </row>
15184      </tbody>
15185     </tgroup>
15186    </table>
15187
15188    <para>
15189     <function>pg_start_backup</> accepts an
15190     arbitrary user-defined label for the backup.  (Typically this would be
15191     the name under which the backup dump file will be stored.)  The function
15192     writes a backup label file (<filename>backup_label</>) into the
15193     database cluster's data directory, performs a checkpoint,
15194     and then returns the backup's starting transaction log location as text.
15195     The user can ignore this result value, but it is
15196     provided in case it is useful.
15197 <programlisting>
15198 postgres=# select pg_start_backup('label_goes_here');
15199  pg_start_backup
15200 -----------------
15201  0/D4445B8
15202 (1 row)
15203 </programlisting>
15204     There is an optional second parameter of type <type>boolean</type>.  If <literal>true</>,
15205     it specifies executing <function>pg_start_backup</> as quickly as
15206     possible.  This forces an immediate checkpoint which will cause a
15207     spike in I/O operations, slowing any concurrently executing queries.
15208    </para>
15209
15210    <para>
15211     <function>pg_stop_backup</> removes the label file created by
15212     <function>pg_start_backup</>, and creates a backup history file in
15213     the transaction log archive area.  The history file includes the label given to
15214     <function>pg_start_backup</>, the starting and ending transaction log locations for
15215     the backup, and the starting and ending times of the backup.  The return
15216     value is the backup's ending transaction log location (which again
15217     can be ignored).  After recording the ending location, the current
15218     transaction log insertion
15219     point is automatically advanced to the next transaction log file, so that the
15220     ending transaction log file can be archived immediately to complete the backup.
15221    </para>
15222
15223    <para>
15224     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the
15225     current file to be archived (assuming you are using continuous archiving).
15226     The return value is the ending transaction log location + 1 within the just-completed transaction log file.
15227     If there has been no transaction log activity since the last transaction log switch,
15228     <function>pg_switch_xlog</> does nothing and returns the start location
15229     of the transaction log file currently in use.
15230    </para>
15231
15232    <para>
15233     <function>pg_create_restore_point</> creates a named transaction log
15234     record that can be used as recovery target, and returns the corresponding
15235     transaction log location.  The given name can then be used with
15236     <xref linkend="recovery-target-name"> to specify the point up to which
15237     recovery will proceed.  Avoid creating multiple restore points with the
15238     same name, since recovery will stop at the first one whose name matches
15239     the recovery target.
15240    </para>
15241
15242    <para>
15243     <function>pg_current_xlog_location</> displays the current transaction log write
15244     location in the same format used by the above functions.  Similarly,
15245     <function>pg_current_xlog_insert_location</> displays the current transaction log
15246     insertion point.  The insertion point is the <quote>logical</> end
15247     of the transaction log
15248     at any instant, while the write location is the end of what has actually
15249     been written out from the server's internal buffers.  The write location
15250     is the end of what can be examined from outside the server, and is usually
15251     what you want if you are interested in archiving partially-complete transaction log
15252     files.  The insertion point is made available primarily for server
15253     debugging purposes.  These are both read-only operations and do not
15254     require superuser permissions.
15255    </para>
15256
15257    <para>
15258     You can use <function>pg_xlogfile_name_offset</> to extract the
15259     corresponding transaction log file name and byte offset from the results of any of the
15260     above functions.  For example:
15261 <programlisting>
15262 postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup());
15263         file_name         | file_offset 
15264 --------------------------+-------------
15265  00000001000000000000000D |     4039624
15266 (1 row)
15267 </programlisting>
15268     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
15269     When the given transaction log location is exactly at a transaction log file boundary, both
15270     these functions return the name of the preceding transaction log file.
15271     This is usually the desired behavior for managing transaction log archiving
15272     behavior, since the preceding file is the last one that currently
15273     needs to be archived.
15274    </para>
15275
15276    <para>
15277     <function>pg_xlog_location_diff</> calculates the difference in bytes
15278     between two transaction log locations. It can be used with
15279     <structname>pg_stat_replication</structname> or some functions shown in
15280     <xref linkend="functions-admin-backup-table"> to get the replication lag.
15281    </para>
15282
15283    <para>
15284     For details about proper usage of these functions, see
15285     <xref linkend="continuous-archiving">.
15286    </para>
15287
15288   </sect2>
15289
15290   <sect2 id="functions-recovery-control">
15291    <title>Recovery Control Functions</title>
15292
15293    <indexterm>
15294     <primary>pg_is_in_recovery</primary>
15295    </indexterm>
15296    <indexterm>
15297     <primary>pg_last_xlog_receive_location</primary>
15298    </indexterm>
15299    <indexterm>
15300     <primary>pg_last_xlog_replay_location</primary>
15301    </indexterm>
15302    <indexterm>
15303     <primary>pg_last_xact_replay_timestamp</primary>
15304    </indexterm>
15305
15306    <para>
15307     The functions shown in <xref
15308     linkend="functions-recovery-info-table"> provide information
15309     about the current status of the standby.
15310     These functions may be executed both during recovery and in normal running.
15311    </para>
15312
15313    <table id="functions-recovery-info-table">
15314     <title>Recovery Information Functions</title>
15315     <tgroup cols="3">
15316      <thead>
15317       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15318       </row>
15319      </thead>
15320
15321      <tbody>
15322       <row>
15323        <entry>
15324         <literal><function>pg_is_in_recovery()</function></literal>
15325         </entry>
15326        <entry><type>bool</type></entry>
15327        <entry>True if recovery is still in progress.
15328        </entry>
15329       </row>
15330       <row>
15331        <entry>
15332         <literal><function>pg_last_xlog_receive_location()</function></literal>
15333         </entry>
15334        <entry><type>text</type></entry>
15335        <entry>Get last transaction log location received and synced to disk by
15336         streaming replication. While streaming replication is in progress
15337         this will increase monotonically. If recovery has completed this will
15338         remain static at
15339         the value of the last WAL record received and synced to disk during
15340         recovery. If streaming replication is disabled, or if it has not yet
15341         started, the function returns NULL.
15342        </entry>
15343       </row>
15344       <row>
15345        <entry>
15346         <literal><function>pg_last_xlog_replay_location()</function></literal>
15347         </entry>
15348        <entry><type>text</type></entry>
15349        <entry>Get last transaction log location replayed during recovery.
15350         If recovery is still in progress this will increase monotonically.
15351         If recovery has completed then this value will remain static at
15352         the value of the last WAL record applied during that recovery.
15353         When the server has been started normally without recovery
15354         the function returns NULL.
15355        </entry>
15356       </row>
15357       <row>
15358        <entry>
15359         <literal><function>pg_last_xact_replay_timestamp()</function></literal>
15360         </entry>
15361        <entry><type>timestamp with time zone</type></entry>
15362        <entry>Get time stamp of last transaction replayed during recovery.
15363         This is the time at which the commit or abort WAL record for that
15364         transaction was generated on the primary.
15365         If no transactions have been replayed during recovery, this function
15366         returns NULL.  Otherwise, if recovery is still in progress this will
15367         increase monotonically.  If recovery has completed then this value will
15368         remain static at the value of the last transaction applied during that
15369         recovery.  When the server has been started normally without recovery
15370         the function returns NULL.
15371        </entry>
15372       </row>
15373      </tbody>
15374     </tgroup>
15375    </table>
15376
15377    <indexterm>
15378     <primary>pg_is_xlog_replay_paused</primary>
15379    </indexterm>
15380    <indexterm>
15381     <primary>pg_xlog_replay_pause</primary>
15382    </indexterm>
15383    <indexterm>
15384     <primary>pg_xlog_replay_resume</primary>
15385    </indexterm>
15386
15387    <para>
15388     The functions shown in <xref
15389     linkend="functions-recovery-control-table"> control the progress of recovery.
15390     These functions may be executed only during recovery.
15391    </para>
15392
15393    <table id="functions-recovery-control-table">
15394     <title>Recovery Control Functions</title>
15395     <tgroup cols="3">
15396      <thead>
15397       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15398       </row>
15399      </thead>
15400
15401      <tbody>
15402       <row>
15403        <entry>
15404         <literal><function>pg_is_xlog_replay_paused()</function></literal>
15405         </entry>
15406        <entry><type>bool</type></entry>
15407        <entry>True if recovery is paused.
15408        </entry>
15409       </row>
15410       <row>
15411        <entry>
15412         <literal><function>pg_xlog_replay_pause()</function></literal>
15413         </entry>
15414        <entry><type>void</type></entry>
15415        <entry>Pauses recovery immediately.
15416        </entry>
15417       </row>
15418       <row>
15419        <entry>
15420         <literal><function>pg_xlog_replay_resume()</function></literal>
15421         </entry>
15422        <entry><type>void</type></entry>
15423        <entry>Restarts recovery if it was paused.
15424        </entry>
15425       </row>
15426      </tbody>
15427     </tgroup>
15428    </table>
15429
15430    <para>
15431     While recovery is paused no further database changes are applied.
15432     If in hot standby, all new queries will see the same consistent snapshot
15433     of the database, and no further query conflicts will be generated until
15434     recovery is resumed.
15435    </para>
15436
15437    <para>
15438     If streaming replication is disabled, the paused state may continue
15439     indefinitely without problem. While streaming replication is in
15440     progress WAL records will continue to be received, which will
15441     eventually fill available disk space, depending upon the duration of
15442     the pause, the rate of WAL generation and available disk space.
15443    </para>
15444
15445   </sect2>
15446
15447   <sect2 id="functions-snapshot-synchronization">
15448    <title>Snapshot Synchronization Functions</title>
15449
15450    <indexterm>
15451      <primary>pg_export_snapshot</primary>
15452    </indexterm>
15453
15454    <para>
15455     <productname>PostgreSQL</> allows database sessions to synchronize their
15456     snapshots. A <firstterm>snapshot</> determines which data is visible to the
15457     transaction that is using the snapshot. Synchronized snapshots are
15458     necessary when two or more sessions need to see identical content in the
15459     database. If two sessions just start their transactions independently,
15460     there is always a possibility that some third transaction commits
15461     between the executions of the two <command>START TRANSACTION</> commands,
15462     so that one session sees the effects of that transaction and the other
15463     does not.
15464    </para>
15465
15466    <para>
15467     To solve this problem, <productname>PostgreSQL</> allows a transaction to
15468     <firstterm>export</> the snapshot it is using.  As long as the exporting
15469     transaction remains open, other transactions can <firstterm>import</> its
15470     snapshot, and thereby be guaranteed that they see exactly the same view
15471     of the database that the first transaction sees.  But note that any
15472     database changes made by any one of these transactions remain invisible
15473     to the other transactions, as is usual for changes made by uncommitted
15474     transactions.  So the transactions are synchronized with respect to
15475     pre-existing data, but act normally for changes they make themselves.
15476    </para>
15477
15478    <para>
15479     Snapshots are exported with the <function>pg_export_snapshot</> function,
15480     shown in <xref linkend="functions-snapshot-synchronization-table">, and
15481     imported with the <xref linkend="sql-set-transaction"> command.
15482    </para>
15483
15484    <table id="functions-snapshot-synchronization-table">
15485     <title>Snapshot Synchronization Functions</title>
15486     <tgroup cols="3">
15487      <thead>
15488       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15489       </row>
15490      </thead>
15491
15492      <tbody>
15493       <row>
15494        <entry>
15495         <literal><function>pg_export_snapshot()</function></literal>
15496        </entry>
15497        <entry><type>text</type></entry>
15498        <entry>Save the current snapshot and return its identifier</entry>
15499       </row>
15500      </tbody>
15501     </tgroup>
15502    </table>
15503
15504    <para>
15505     The function <function>pg_export_snapshot</> saves the current snapshot
15506     and returns a <type>text</> string identifying the snapshot.  This string
15507     must be passed (outside the database) to clients that want to import the
15508     snapshot.  The snapshot is available for import only until the end of the
15509     transaction that exported it.  A transaction can export more than one
15510     snapshot, if needed.  Note that doing so is only useful in <literal>READ
15511     COMMITTED</> transactions, since in <literal>REPEATABLE READ</> and
15512     higher isolation levels, transactions use the same snapshot throughout
15513     their lifetime.  Once a transaction has exported any snapshots, it cannot
15514     be prepared with <xref linkend="sql-prepare-transaction">.
15515    </para>
15516
15517    <para>
15518     See  <xref linkend="sql-set-transaction"> for details of how to use an
15519     exported snapshot.
15520    </para>
15521   </sect2>
15522
15523   <sect2 id="functions-admin-dbobject">
15524    <title>Database Object Management Functions</title>
15525
15526    <para>
15527     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
15528     the disk space usage of database objects.
15529    </para>
15530
15531    <indexterm>
15532     <primary>pg_column_size</primary>
15533    </indexterm>
15534    <indexterm>
15535     <primary>pg_database_size</primary>
15536    </indexterm>
15537    <indexterm>
15538     <primary>pg_indexes_size</primary>
15539    </indexterm>
15540    <indexterm>
15541     <primary>pg_relation_size</primary>
15542    </indexterm>
15543    <indexterm>
15544     <primary>pg_size_pretty</primary>
15545    </indexterm>
15546    <indexterm>
15547     <primary>pg_table_size</primary>
15548    </indexterm>
15549    <indexterm>
15550     <primary>pg_tablespace_size</primary>
15551    </indexterm>
15552    <indexterm>
15553     <primary>pg_total_relation_size</primary>
15554    </indexterm>
15555
15556    <table id="functions-admin-dbsize">
15557     <title>Database Object Size Functions</title>
15558     <tgroup cols="3">
15559      <thead>
15560       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15561       </row>
15562      </thead>
15563
15564      <tbody>
15565       <row>
15566        <entry><literal><function>pg_column_size(<type>any</type>)</function></literal></entry>
15567        <entry><type>int</type></entry>
15568        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
15569       </row>
15570       <row>
15571        <entry>
15572         <literal><function>pg_database_size(<type>oid</type>)</function></literal>
15573         </entry>
15574        <entry><type>bigint</type></entry>
15575        <entry>Disk space used by the database with the specified OID</entry>
15576       </row>
15577       <row>
15578        <entry>
15579         <literal><function>pg_database_size(<type>name</type>)</function></literal>
15580         </entry>
15581        <entry><type>bigint</type></entry>
15582        <entry>Disk space used by the database with the specified name</entry>
15583       </row>
15584       <row>
15585        <entry>
15586         <literal><function>pg_indexes_size(<type>regclass</type>)</function></literal>
15587         </entry>
15588        <entry><type>bigint</type></entry>
15589        <entry>
15590         Total disk space used by indexes attached to the specified table
15591        </entry>
15592       </row>
15593       <row>
15594        <entry>
15595         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</function></literal>
15596         </entry>
15597        <entry><type>bigint</type></entry>
15598        <entry>
15599         Disk space used by the specified fork (<literal>'main'</literal>,
15600         <literal>'fsm'</literal> or <literal>'vm'</>)
15601         of the specified table or index
15602        </entry>
15603       </row>
15604       <row>
15605        <entry>
15606         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
15607         </entry>
15608        <entry><type>bigint</type></entry>
15609        <entry>
15610         Shorthand for <literal>pg_relation_size(..., 'main')</literal>
15611        </entry>
15612       </row>
15613       <row>
15614        <entry>
15615         <literal><function>pg_size_pretty(<type>bigint</type>)</function></literal>
15616         </entry>
15617        <entry><type>text</type></entry>
15618        <entry>
15619          Converts a size in bytes expressed as a 64-bit integer into a
15620          human-readable format with size units
15621        </entry>
15622       </row>
15623       <row>
15624        <entry>
15625         <literal><function>pg_size_pretty(<type>numeric</type>)</function></literal>
15626         </entry>
15627        <entry><type>text</type></entry>
15628        <entry>
15629          Converts a size in bytes expressed as a numeric value into a
15630          human-readable format with size units
15631        </entry>
15632       </row>
15633       <row>
15634        <entry>
15635         <literal><function>pg_table_size(<type>regclass</type>)</function></literal>
15636         </entry>
15637        <entry><type>bigint</type></entry>
15638        <entry>
15639         Disk space used by the specified table, excluding indexes
15640         (but including TOAST, free space map, and visibility map)
15641        </entry>
15642       </row>
15643       <row>
15644        <entry>
15645         <literal><function>pg_tablespace_size(<type>oid</type>)</function></literal>
15646         </entry>
15647        <entry><type>bigint</type></entry>
15648        <entry>Disk space used by the tablespace with the specified OID</entry>
15649       </row>
15650       <row>
15651        <entry>
15652         <literal><function>pg_tablespace_size(<type>name</type>)</function></literal>
15653         </entry>
15654        <entry><type>bigint</type></entry>
15655        <entry>Disk space used by the tablespace with the specified name</entry>
15656       </row>
15657       <row>
15658        <entry>
15659         <literal><function>pg_total_relation_size(<type>regclass</type>)</function></literal>
15660         </entry>
15661        <entry><type>bigint</type></entry>
15662        <entry>
15663         Total disk space used by the specified table,
15664         including all indexes and <acronym>TOAST</> data
15665        </entry>
15666       </row>
15667      </tbody>
15668     </tgroup>
15669    </table>
15670
15671    <para>
15672     <function>pg_column_size</> shows the space used to store any individual
15673     data value.
15674    </para>
15675
15676    <para>
15677     <function>pg_total_relation_size</> accepts the OID or name of a
15678     table or toast table, and returns the total on-disk space used for
15679     that table, including all associated indexes.  This function is
15680     equivalent to <function>pg_table_size</function>
15681     <literal>+</> <function>pg_indexes_size</function>.
15682    </para>
15683
15684    <para>
15685     <function>pg_table_size</> accepts the OID or name of a table and
15686     returns the disk space needed for that table, exclusive of indexes.
15687     (TOAST space, free space map, and visibility map are included.)
15688    </para>
15689
15690    <para>
15691     <function>pg_indexes_size</> accepts the OID or name of a table and
15692     returns the total disk space used by all the indexes attached to that
15693     table.
15694    </para>
15695
15696    <para>
15697     <function>pg_database_size</function> and <function>pg_tablespace_size</>
15698     accept the OID or name of a database or tablespace, and return the total
15699     disk space used therein.
15700    </para>
15701
15702    <para>
15703     <function>pg_relation_size</> accepts the OID or name of a table, index or
15704     toast table, and returns the on-disk size in bytes. Specifying
15705     <literal>'main'</literal> or leaving out the second argument returns the
15706     size of the main data fork of the relation. Specifying
15707     <literal>'fsm'</literal> returns the size of the
15708     Free Space Map (see <xref linkend="storage-fsm">) associated with the
15709     relation. Specifying <literal>'vm'</literal> returns the size of the
15710     Visibility Map (see <xref linkend="storage-vm">) associated with the
15711     relation.  Note that this function shows the size of only one fork;
15712     for most purposes it is more convenient to use the higher-level
15713     functions <function>pg_total_relation_size</> or
15714     <function>pg_table_size</>.
15715    </para>
15716
15717    <para>
15718     <function>pg_size_pretty</> can be used to format the result of one of
15719     the other functions in a human-readable way, using kB, MB, GB or TB as
15720     appropriate.
15721    </para>
15722
15723    <para>
15724     The functions above that operate on tables or indexes accept a
15725     <type>regclass</> argument, which is simply the OID of the table or index
15726     in the <structname>pg_class</> system catalog.  You do not have to look up
15727     the OID by hand, however, since the <type>regclass</> data type's input
15728     converter will do the work for you.  Just write the table name enclosed in
15729     single quotes so that it looks like a literal constant.  For compatibility
15730     with the handling of ordinary <acronym>SQL</acronym> names, the string
15731     will be converted to lower case unless it contains double quotes around
15732     the table name.
15733    </para>
15734
15735    <para>
15736     If an OID that does not represent an existing object is passed as
15737     argument to one of the above functions, NULL is returned.
15738    </para>
15739
15740    <para>
15741     The functions shown in <xref linkend="functions-admin-dblocation"> assist
15742     in identifying the specific disk files associated with database objects.
15743    </para>
15744
15745    <indexterm>
15746     <primary>pg_relation_filenode</primary>
15747    </indexterm>
15748    <indexterm>
15749     <primary>pg_relation_filepath</primary>
15750    </indexterm>
15751
15752    <table id="functions-admin-dblocation">
15753     <title>Database Object Location Functions</title>
15754     <tgroup cols="3">
15755      <thead>
15756       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15757       </row>
15758      </thead>
15759
15760      <tbody>
15761       <row>
15762        <entry>
15763         <literal><function>pg_relation_filenode(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
15764         </entry>
15765        <entry><type>oid</type></entry>
15766        <entry>
15767         Filenode number of the specified relation
15768        </entry>
15769       </row>
15770       <row>
15771        <entry>
15772         <literal><function>pg_relation_filepath(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
15773         </entry>
15774        <entry><type>text</type></entry>
15775        <entry>
15776         File path name of the specified relation
15777        </entry>
15778       </row>
15779      </tbody>
15780     </tgroup>
15781    </table>
15782
15783    <para>
15784     <function>pg_relation_filenode</> accepts the OID or name of a table,
15785     index, sequence, or toast table, and returns the <quote>filenode</> number
15786     currently assigned to it.  The filenode is the base component of the file
15787     name(s) used for the relation (see <xref linkend="storage-file-layout">
15788     for more information).  For most tables the result is the same as
15789     <structname>pg_class</>.<structfield>relfilenode</>, but for certain
15790     system catalogs <structfield>relfilenode</> is zero and this function must
15791     be used to get the correct value.  The function returns NULL if passed
15792     a relation that does not have storage, such as a view.
15793    </para>
15794
15795    <para>
15796     <function>pg_relation_filepath</> is similar to
15797     <function>pg_relation_filenode</>, but it returns the entire file path name
15798     (relative to the database cluster's data directory <varname>PGDATA</>) of
15799     the relation.
15800    </para>
15801
15802   </sect2>
15803
15804   <sect2 id="functions-admin-genfile">
15805    <title>Generic File Access Functions</title>
15806
15807    <para>
15808     The functions shown in <xref
15809     linkend="functions-admin-genfile-table"> provide native access to
15810     files on the machine hosting the server. Only files within the
15811     database cluster directory and the <varname>log_directory</> can be
15812     accessed.  Use a relative path for files in the cluster directory,
15813     and a path matching the <varname>log_directory</> configuration setting
15814     for log files.  Use of these functions is restricted to superusers.
15815    </para>
15816
15817    <table id="functions-admin-genfile-table">
15818     <title>Generic File Access Functions</title>
15819     <tgroup cols="3">
15820      <thead>
15821       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15822       </row>
15823      </thead>
15824
15825      <tbody>
15826       <row>
15827        <entry>
15828         <literal><function>pg_ls_dir(<parameter>dirname</> <type>text</>)</function></literal>
15829        </entry>
15830        <entry><type>setof text</type></entry>
15831        <entry>List the contents of a directory</entry>
15832       </row>
15833       <row>
15834        <entry>
15835         <literal><function>pg_read_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
15836        </entry>
15837        <entry><type>text</type></entry>
15838        <entry>Return the contents of a text file</entry>
15839       </row>
15840       <row>
15841        <entry>
15842         <literal><function>pg_read_binary_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
15843        </entry>
15844        <entry><type>bytea</type></entry>
15845        <entry>Return the contents of a file</entry>
15846       </row>
15847       <row>
15848        <entry>
15849         <literal><function>pg_stat_file(<parameter>filename</> <type>text</>)</function></literal>
15850        </entry>
15851        <entry><type>record</type></entry>
15852        <entry>Return information about a file</entry>
15853       </row>
15854      </tbody>
15855     </tgroup>
15856    </table>
15857
15858    <indexterm>
15859     <primary>pg_ls_dir</primary>
15860    </indexterm>
15861    <para>
15862     <function>pg_ls_dir</> returns all the names in the specified
15863     directory, except the special entries <quote><literal>.</></> and
15864     <quote><literal>..</></>.
15865    </para>
15866
15867    <indexterm>
15868     <primary>pg_read_file</primary>
15869    </indexterm>
15870    <para>
15871     <function>pg_read_file</> returns part of a text file, starting
15872     at the given <parameter>offset</>, returning at most <parameter>length</>
15873     bytes (less if the end of file is reached first).  If <parameter>offset</>
15874     is negative, it is relative to the end of the file.
15875     If <parameter>offset</> and <parameter>length</> are omitted, the entire
15876     file is returned.  The bytes read from the file are interpreted as a string
15877     in the server encoding; an error is thrown if they are not valid in that
15878     encoding.
15879    </para>
15880
15881    <indexterm>
15882     <primary>pg_read_binary_file</primary>
15883    </indexterm>
15884    <para>
15885     <function>pg_read_binary_file</> is similar to
15886     <function>pg_read_file</>, except that the result is a <type>bytea</type> value;
15887     accordingly, no encoding checks are performed.
15888     In combination with the <function>convert_from</> function, this function
15889     can be used to read a file in a specified encoding:
15890 <programlisting>
15891 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
15892 </programlisting>
15893    </para>
15894
15895    <indexterm>
15896     <primary>pg_stat_file</primary>
15897    </indexterm>
15898    <para>
15899     <function>pg_stat_file</> returns a record containing the file
15900     size, last accessed time stamp, last modified time stamp,
15901     last file status change time stamp (Unix platforms only),
15902     file creation time stamp (Windows only), and a <type>boolean</type>
15903     indicating if it is a directory.  Typical usages include:
15904 <programlisting>
15905 SELECT * FROM pg_stat_file('filename');
15906 SELECT (pg_stat_file('filename')).modification;
15907 </programlisting>
15908    </para>
15909
15910   </sect2>
15911
15912   <sect2 id="functions-advisory-locks">
15913    <title>Advisory Lock Functions</title>
15914
15915    <para>
15916     The functions shown in <xref linkend="functions-advisory-locks-table">
15917     manage advisory locks.  For details about proper use of these functions,
15918     see <xref linkend="advisory-locks">.
15919    </para>
15920
15921    <table id="functions-advisory-locks-table">
15922     <title>Advisory Lock Functions</title>
15923     <tgroup cols="3">
15924      <thead>
15925       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15926       </row>
15927      </thead>
15928
15929      <tbody>
15930       <row>
15931        <entry>
15932         <literal><function>pg_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
15933        </entry>
15934        <entry><type>void</type></entry>
15935        <entry>Obtain exclusive session level advisory lock</entry>
15936       </row>
15937       <row>
15938        <entry>
15939         <literal><function>pg_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15940        </entry>
15941        <entry><type>void</type></entry>
15942        <entry>Obtain exclusive session level advisory lock</entry>
15943       </row>
15944       <row>
15945        <entry>
15946         <literal><function>pg_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
15947        </entry>
15948        <entry><type>void</type></entry>
15949        <entry>Obtain shared session level advisory lock</entry>
15950       </row>
15951       <row>
15952        <entry>
15953         <literal><function>pg_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15954        </entry>
15955        <entry><type>void</type></entry>
15956        <entry>Obtain shared session level advisory lock</entry>
15957       </row>
15958       <row>
15959        <entry>
15960         <literal><function>pg_advisory_unlock(<parameter>key</> <type>bigint</>)</function></literal>
15961        </entry>
15962        <entry><type>boolean</type></entry>
15963        <entry>Release an exclusive session level advisory lock</entry>
15964       </row>
15965       <row>
15966        <entry>
15967         <literal><function>pg_advisory_unlock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15968        </entry>
15969        <entry><type>boolean</type></entry>
15970        <entry>Release an exclusive session level advisory lock</entry>
15971       </row>
15972       <row>
15973        <entry>
15974         <literal><function>pg_advisory_unlock_all()</function></literal>
15975        </entry>
15976        <entry><type>void</type></entry>
15977        <entry>Release all session level advisory locks held by the current session</entry>
15978       </row>
15979       <row>
15980        <entry>
15981         <literal><function>pg_advisory_unlock_shared(<parameter>key</> <type>bigint</>)</function></literal>
15982        </entry>
15983        <entry><type>boolean</type></entry>
15984        <entry>Release a shared session level advisory lock</entry>
15985       </row>
15986       <row>
15987        <entry>
15988         <literal><function>pg_advisory_unlock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15989        </entry>
15990        <entry><type>boolean</type></entry>
15991        <entry>Release a shared session level advisory lock</entry>
15992       </row>
15993       <row>
15994        <entry>
15995         <literal><function>pg_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
15996        </entry>
15997        <entry><type>void</type></entry>
15998        <entry>Obtain exclusive transaction level advisory lock</entry>
15999       </row>
16000       <row>
16001        <entry>
16002         <literal><function>pg_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
16003        </entry>
16004        <entry><type>void</type></entry>
16005        <entry>Obtain exclusive transaction level advisory lock</entry>
16006       </row>
16007       <row>
16008        <entry>
16009         <literal><function>pg_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
16010        </entry>
16011        <entry><type>void</type></entry>
16012        <entry>Obtain shared transaction level advisory lock</entry>
16013       </row>
16014       <row>
16015        <entry>
16016         <literal><function>pg_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
16017        </entry>
16018        <entry><type>void</type></entry>
16019        <entry>Obtain shared transaction level advisory lock</entry>
16020       </row>
16021       <row>
16022        <entry>
16023         <literal><function>pg_try_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
16024        </entry>
16025        <entry><type>boolean</type></entry>
16026        <entry>Obtain exclusive session level advisory lock if available</entry>
16027       </row>
16028       <row>
16029        <entry>
16030         <literal><function>pg_try_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
16031        </entry>
16032        <entry><type>boolean</type></entry>
16033        <entry>Obtain exclusive session level advisory lock if available</entry>
16034       </row>
16035       <row>
16036        <entry>
16037         <literal><function>pg_try_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
16038        </entry>
16039        <entry><type>boolean</type></entry>
16040        <entry>Obtain shared session level advisory lock if available</entry>
16041       </row>
16042       <row>
16043        <entry>
16044         <literal><function>pg_try_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
16045        </entry>
16046        <entry><type>boolean</type></entry>
16047        <entry>Obtain shared session level advisory lock if available</entry>
16048       </row>
16049       <row>
16050        <entry>
16051         <literal><function>pg_try_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
16052        </entry>
16053        <entry><type>boolean</type></entry>
16054        <entry>Obtain exclusive transaction level advisory lock if available</entry>
16055       </row>
16056       <row>
16057        <entry>
16058         <literal><function>pg_try_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
16059        </entry>
16060        <entry><type>boolean</type></entry>
16061        <entry>Obtain exclusive transaction level advisory lock if available</entry>
16062       </row>
16063       <row>
16064        <entry>
16065         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
16066        </entry>
16067        <entry><type>boolean</type></entry>
16068        <entry>Obtain shared transaction level advisory lock if available</entry>
16069       </row>
16070       <row>
16071        <entry>
16072         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
16073        </entry>
16074        <entry><type>boolean</type></entry>
16075        <entry>Obtain shared transaction level advisory lock if available</entry>
16076       </row>
16077      </tbody>
16078     </tgroup>
16079    </table>
16080
16081    <indexterm>
16082     <primary>pg_advisory_lock</primary>
16083    </indexterm>
16084    <para>
16085     <function>pg_advisory_lock</> locks an application-defined resource,
16086     which can be identified either by a single 64-bit key value or two
16087     32-bit key values (note that these two key spaces do not overlap).
16088     If another session already holds a lock on the same resource identifier,
16089     this function will wait until the resource becomes available.  The lock
16090     is exclusive.  Multiple lock requests stack, so that if the same resource
16091     is locked three times it must then be unlocked three times to be
16092     released for other sessions' use.
16093    </para>
16094
16095    <indexterm>
16096     <primary>pg_advisory_lock_shared</primary>
16097    </indexterm>
16098    <para>
16099     <function>pg_advisory_lock_shared</> works the same as
16100     <function>pg_advisory_lock</>,
16101     except the lock can be shared with other sessions requesting shared locks.
16102     Only would-be exclusive lockers are locked out.
16103    </para>
16104
16105    <indexterm>
16106     <primary>pg_try_advisory_lock</primary>
16107    </indexterm>
16108    <para>
16109     <function>pg_try_advisory_lock</> is similar to
16110     <function>pg_advisory_lock</>, except the function will not wait for the
16111     lock to become available.  It will either obtain the lock immediately and
16112     return <literal>true</>, or return <literal>false</> if the lock cannot be
16113     acquired immediately.
16114    </para>
16115
16116    <indexterm>
16117     <primary>pg_try_advisory_lock_shared</primary>
16118    </indexterm>
16119    <para>
16120     <function>pg_try_advisory_lock_shared</> works the same as
16121     <function>pg_try_advisory_lock</>, except it attempts to acquire
16122     a shared rather than an exclusive lock.
16123    </para>
16124
16125    <indexterm>
16126     <primary>pg_advisory_unlock</primary>
16127    </indexterm>
16128    <para>
16129     <function>pg_advisory_unlock</> will release a previously-acquired
16130     exclusive session level advisory lock.  It
16131     returns <literal>true</> if the lock is successfully released.
16132     If the lock was not held, it will return <literal>false</>,
16133     and in addition, an SQL warning will be reported by the server.
16134    </para>
16135
16136    <indexterm>
16137     <primary>pg_advisory_unlock_shared</primary>
16138    </indexterm>
16139    <para>
16140     <function>pg_advisory_unlock_shared</> works the same as
16141     <function>pg_advisory_unlock</>,
16142     except it releases a shared session level advisory lock.
16143    </para>
16144
16145    <indexterm>
16146     <primary>pg_advisory_unlock_all</primary>
16147    </indexterm>
16148    <para>
16149     <function>pg_advisory_unlock_all</> will release all session level advisory
16150     locks held by the current session.  (This function is implicitly invoked
16151     at session end, even if the client disconnects ungracefully.)
16152    </para>
16153
16154    <indexterm>
16155     <primary>pg_advisory_xact_lock</primary>
16156    </indexterm>
16157    <para>
16158     <function>pg_advisory_xact_lock</> works the same as
16159     <function>pg_advisory_lock</>, except the lock is automatically released
16160     at the end of the current transaction and cannot be released explicitly.
16161    </para>
16162
16163    <indexterm>
16164     <primary>pg_advisory_xact_lock_shared</primary>
16165    </indexterm>
16166    <para>
16167     <function>pg_advisory_xact_lock_shared</> works the same as
16168     <function>pg_advisory_lock_shared</>, except the lock is automatically released
16169     at the end of the current transaction and cannot be released explicitly.
16170    </para>
16171
16172    <indexterm>
16173     <primary>pg_try_advisory_xact_lock</primary>
16174    </indexterm>
16175    <para>
16176     <function>pg_try_advisory_xact_lock</> works the same as
16177     <function>pg_try_advisory_lock</>, except the lock, if acquired,
16178     is automatically released at the end of the current transaction and
16179     cannot be released explicitly.
16180    </para>
16181
16182    <indexterm>
16183     <primary>pg_try_advisory_xact_lock_shared</primary>
16184    </indexterm>
16185    <para>
16186     <function>pg_try_advisory_xact_lock_shared</> works the same as
16187     <function>pg_try_advisory_lock_shared</>, except the lock, if acquired,
16188     is automatically released at the end of the current transaction and
16189     cannot be released explicitly.
16190    </para>
16191
16192   </sect2>
16193
16194   </sect1>
16195
16196   <sect1 id="functions-trigger">
16197    <title>Trigger Functions</title>
16198
16199    <indexterm>
16200      <primary>suppress_redundant_updates_trigger</primary>
16201    </indexterm>
16202
16203    <para>
16204       Currently <productname>PostgreSQL</> provides one built in trigger
16205       function, <function>suppress_redundant_updates_trigger</>,
16206       which will prevent any update
16207       that does not actually change the data in the row from taking place, in
16208       contrast to the normal behavior which always performs the update
16209       regardless of whether or not the data has changed. (This normal behavior
16210       makes updates run faster, since no checking is required, and is also
16211       useful in certain cases.)
16212     </para>
16213
16214     <para>
16215       Ideally, you should normally avoid running updates that don't actually
16216       change the data in the record. Redundant updates can cost considerable
16217       unnecessary time, especially if there are lots of indexes to alter,
16218       and space in dead rows that will eventually have to be vacuumed.
16219       However, detecting such situations in client code is not
16220       always easy, or even possible, and writing expressions to detect
16221       them can be error-prone. An alternative is to use
16222       <function>suppress_redundant_updates_trigger</>, which will skip
16223       updates that don't change the data. You should use this with care,
16224       however. The trigger takes a small but non-trivial time for each record,
16225       so if most of the records affected by an update are actually changed,
16226       use of this trigger will actually make the update run slower.
16227     </para>
16228
16229     <para>
16230       The <function>suppress_redundant_updates_trigger</> function can be
16231       added to a table like this:
16232 <programlisting>
16233 CREATE TRIGGER z_min_update
16234 BEFORE UPDATE ON tablename
16235 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
16236 </programlisting>
16237       In most cases, you would want to fire this trigger last for each row.
16238       Bearing in mind that triggers fire in name order, you would then
16239       choose a trigger name that comes after the name of any other trigger
16240       you might have on the table.
16241     </para>
16242     <para>
16243        For more information about creating triggers, see
16244         <xref linkend="SQL-CREATETRIGGER">.
16245     </para>
16246   </sect1>
16247
16248   <sect1 id="functions-event-triggers">
16249    <title>Event Trigger Functions</title>
16250
16251    <indexterm>
16252      <primary>pg_event_trigger_dropped_objects</primary>
16253    </indexterm>
16254
16255    <para>
16256     Currently <productname>PostgreSQL</> provides one built-in event trigger
16257     helper function, <function>pg_event_trigger_dropped_objects</>.
16258    </para>
16259
16260    <para>
16261     <function>pg_event_trigger_dropped_objects</> returns a list of all object
16262     dropped by the command in whose <literal>sql_drop</> event it is called.
16263     If called in any other context,
16264     <function>pg_event_trigger_dropped_objects</> raises an error.
16265     <function>pg_event_trigger_dropped_objects</> returns the following columns:
16266
16267     <informaltable>
16268      <tgroup cols="3">
16269       <thead>
16270        <row>
16271         <entry>Name</entry>
16272         <entry>Type</entry>
16273         <entry>Description</entry>
16274        </row>
16275       </thead>
16276
16277       <tbody>
16278        <row>
16279         <entry><literal>classid</literal></entry>
16280         <entry><type>Oid</type></entry>
16281         <entry>OID of catalog the object belonged in</entry>
16282        </row>
16283        <row>
16284         <entry><literal>objid</literal></entry>
16285         <entry><type>Oid</type></entry>
16286         <entry>OID the object had within the catalog</entry>
16287        </row>
16288        <row>
16289         <entry><literal>objsubid</literal></entry>
16290         <entry><type>int32</type></entry>
16291         <entry>Object sub-id (e.g. attribute number for columns)</entry>
16292        </row>
16293        <row>
16294         <entry><literal>object_type</literal></entry>
16295         <entry><type>text</type></entry>
16296         <entry>Type of the object</entry>
16297        </row>
16298        <row>
16299         <entry><literal>schema_name</literal></entry>
16300         <entry><type>text</type></entry>
16301         <entry>
16302          Name of the schema the object belonged in, if any; otherwise <literal>NULL</>.
16303          No quoting is applied.
16304         </entry>
16305        </row>
16306        <row>
16307         <entry><literal>object_name</literal></entry>
16308         <entry><type>text</type></entry>
16309         <entry>
16310          Name of the object, if the combination of schema and name can be
16311          used as an unique identifier for the object; otherwise <literal>NULL</>.
16312          No quoting is applied, and name is never schema-qualified.
16313         </entry>
16314        </row>
16315        <row>
16316         <entry><literal>object_identity</literal></entry>
16317         <entry><type>text</type></entry>
16318         <entry>
16319          Text rendering of the object identity, schema-qualified. Each and every
16320          identifier present in the identity is quoted if necessary.
16321         </entry>
16322        </row>
16323       </tbody>
16324      </tgroup>
16325     </informaltable>
16326    </para>
16327
16328    <para>
16329     The <function>pg_event_trigger_dropped_objects</> function can be used
16330     in an event trigger like this:
16331 <programlisting>
16332 CREATE FUNCTION test_event_trigger_for_drops()
16333         RETURNS event_trigger LANGUAGE plpgsql AS $$
16334 DECLARE
16335     obj record;
16336 BEGIN
16337     FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
16338     LOOP
16339         RAISE NOTICE '% dropped object: % %.% %',
16340                      tg_tag,
16341                      obj.object_type,
16342                      obj.schema_name,
16343                      obj.object_name,
16344                      obj.object_identity;
16345     END LOOP;
16346 END
16347 $$;
16348 CREATE EVENT TRIGGER test_event_trigger_for_drops
16349    ON sql_drop
16350    EXECUTE PROCEDURE test_event_trigger_for_drops();
16351 </programlisting>
16352     </para>
16353
16354      <para>
16355        For more information about event triggers,
16356        see <xref linkend="event-triggers">.
16357     </para>
16358   </sect1>
16359
16360 </chapter>