]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
doc: Tiny whitespace fix
[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</> merely outputs null bytes as <literal>\000</> and
1510         doubles backslashes.
1511        </entry>
1512        <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1513        <entry><literal>MTIzAAE=</literal></entry>
1514       </row>
1515
1516       <row>
1517        <entry id="format">
1518         <indexterm>
1519          <primary>format</primary>
1520         </indexterm>
1521         <literal><function>format</function>(<parameter>formatstr</parameter> <type>text</type>
1522         [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</literal>
1523        </entry>
1524        <entry><type>text</type></entry>
1525        <entry>
1526          Format arguments according to a format string.
1527          This function is similar to the C function
1528          <function>sprintf</>, but only the following conversion specifications
1529          are recognized: <literal>%s</literal> interpolates the corresponding
1530          argument as a string; <literal>%I</literal> escapes its argument as
1531          an SQL identifier; <literal>%L</literal> escapes its argument as an
1532          SQL literal; <literal>%%</literal> outputs a literal <literal>%</>.
1533          A conversion can reference an explicit parameter position by preceding
1534          the conversion specifier with <literal><replaceable>n</>$</>, where
1535          <replaceable>n</replaceable> is the argument position.
1536          See also <xref linkend="plpgsql-quote-literal-example">.
1537        </entry>
1538        <entry><literal>format('Hello %s, %1$s', 'World')</literal></entry>
1539        <entry><literal>Hello World, World</literal></entry>
1540       </row>
1541
1542       <row>
1543        <entry>
1544         <indexterm>
1545          <primary>initcap</primary>
1546         </indexterm>
1547         <literal><function>initcap(<parameter>string</parameter>)</function></literal>
1548        </entry>
1549        <entry><type>text</type></entry>
1550        <entry>
1551         Convert the first letter of each word to upper case and the
1552         rest to lower case. Words are sequences of alphanumeric
1553         characters separated by non-alphanumeric characters.
1554        </entry>
1555        <entry><literal>initcap('hi THOMAS')</literal></entry>
1556        <entry><literal>Hi Thomas</literal></entry>
1557       </row>
1558
1559       <row>
1560        <entry>
1561         <indexterm>
1562          <primary>left</primary>
1563         </indexterm>
1564         <literal><function>left(<parameter>str</parameter> <type>text</type>,
1565         <parameter>n</parameter> <type>int</type>)</function></literal>
1566        </entry>
1567        <entry><type>text</type></entry>
1568        <entry>
1569         Return first <replaceable>n</> characters in the string. When <replaceable>n</>
1570         is negative, return all but last |<replaceable>n</>| characters.
1571         </entry>
1572        <entry><literal>left('abcde', 2)</literal></entry>
1573        <entry><literal>ab</literal></entry>
1574       </row>
1575
1576       <row>
1577        <entry>
1578         <indexterm>
1579          <primary>length</primary>
1580         </indexterm>
1581         <literal><function>length(<parameter>string</parameter>)</function></literal>
1582        </entry>
1583        <entry><type>int</type></entry>
1584        <entry>
1585         Number of characters in <parameter>string</parameter>
1586        </entry>
1587        <entry><literal>length('jose')</literal></entry>
1588        <entry><literal>4</literal></entry>
1589       </row>
1590
1591       <row>
1592        <entry><literal><function>length(<parameter>string</parameter> <type>bytea</type>,
1593         <parameter>encoding</parameter> <type>name</type> )</function></literal></entry>
1594        <entry><type>int</type></entry>
1595        <entry>
1596         Number of characters in <parameter>string</parameter> in the given
1597         <parameter>encoding</parameter>. The <parameter>string</parameter>
1598         must be valid in this encoding.
1599        </entry>
1600        <entry><literal>length('jose', 'UTF8')</literal></entry>
1601        <entry><literal>4</literal></entry>
1602       </row>
1603
1604       <row>
1605        <entry>
1606         <indexterm>
1607          <primary>lpad</primary>
1608         </indexterm>
1609         <literal><function>lpad(<parameter>string</parameter> <type>text</type>,
1610         <parameter>length</parameter> <type>int</type>
1611         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1612        </entry>
1613        <entry><type>text</type></entry>
1614        <entry>
1615         Fill up the <parameter>string</parameter> to length
1616         <parameter>length</parameter> by prepending the characters
1617         <parameter>fill</parameter> (a space by default).  If the
1618         <parameter>string</parameter> is already longer than
1619         <parameter>length</parameter> then it is truncated (on the
1620         right).
1621        </entry>
1622        <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1623        <entry><literal>xyxhi</literal></entry>
1624       </row>
1625
1626       <row>
1627        <entry>
1628         <indexterm>
1629          <primary>ltrim</primary>
1630         </indexterm>
1631         <literal><function>ltrim(<parameter>string</parameter> <type>text</type>
1632         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1633        </entry>
1634        <entry><type>text</type></entry>
1635        <entry>
1636         Remove the longest string containing only characters from
1637         <parameter>characters</parameter> (a space by default) from the start of
1638         <parameter>string</parameter>
1639        </entry>
1640        <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
1641        <entry><literal>trim</literal></entry>
1642       </row>
1643
1644       <row>
1645        <entry>
1646         <indexterm>
1647          <primary>md5</primary>
1648         </indexterm>
1649         <literal><function>md5(<parameter>string</parameter>)</function></literal>
1650        </entry>
1651        <entry><type>text</type></entry>
1652        <entry>
1653         Calculates the MD5 hash of <parameter>string</parameter>,
1654         returning the result in hexadecimal
1655        </entry>
1656        <entry><literal>md5('abc')</literal></entry>
1657        <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1658       </row>
1659
1660       <row>
1661        <entry>
1662         <indexterm>
1663          <primary>pg_client_encoding</primary>
1664         </indexterm>
1665         <literal><function>pg_client_encoding()</function></literal>
1666        </entry>
1667        <entry><type>name</type></entry>
1668        <entry>
1669         Current client encoding name
1670        </entry>
1671        <entry><literal>pg_client_encoding()</literal></entry>
1672        <entry><literal>SQL_ASCII</literal></entry>
1673       </row>
1674
1675       <row>
1676        <entry>
1677         <indexterm>
1678          <primary>quote_ident</primary>
1679         </indexterm>
1680         <literal><function>quote_ident(<parameter>string</parameter> <type>text</type>)</function></literal>
1681        </entry>
1682        <entry><type>text</type></entry>
1683        <entry>
1684         Return the given string suitably quoted to be used as an identifier
1685         in an <acronym>SQL</acronym> statement string.
1686         Quotes are added only if necessary (i.e., if the string contains
1687         non-identifier characters or would be case-folded).
1688         Embedded quotes are properly doubled.
1689         See also <xref linkend="plpgsql-quote-literal-example">.
1690        </entry>
1691        <entry><literal>quote_ident('Foo bar')</literal></entry>
1692        <entry><literal>"Foo bar"</literal></entry>
1693       </row>
1694
1695       <row>
1696        <entry>
1697         <indexterm>
1698          <primary>quote_literal</primary>
1699         </indexterm>
1700         <literal><function>quote_literal(<parameter>string</parameter> <type>text</type>)</function></literal>
1701        </entry>
1702        <entry><type>text</type></entry>
1703        <entry>
1704         Return the given string suitably quoted to be used as a string literal
1705         in an <acronym>SQL</acronym> statement string.
1706         Embedded single-quotes and backslashes are properly doubled.
1707         Note that <function>quote_literal</function> returns null on null
1708         input; if the argument might be null,
1709         <function>quote_nullable</function> is often more suitable.
1710         See also <xref linkend="plpgsql-quote-literal-example">.
1711        </entry>
1712        <entry><literal>quote_literal(E'O\'Reilly')</literal></entry>
1713        <entry><literal>'O''Reilly'</literal></entry>
1714       </row>
1715
1716       <row>
1717        <entry><literal><function>quote_literal(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1718        <entry><type>text</type></entry>
1719        <entry>
1720         Coerce the given value to text and then quote it as a literal.
1721         Embedded single-quotes and backslashes are properly doubled.
1722        </entry>
1723        <entry><literal>quote_literal(42.5)</literal></entry>
1724        <entry><literal>'42.5'</literal></entry>
1725       </row>
1726
1727       <row>
1728        <entry>
1729         <indexterm>
1730          <primary>quote_nullable</primary>
1731         </indexterm>
1732         <literal><function>quote_nullable(<parameter>string</parameter> <type>text</type>)</function></literal>
1733        </entry>
1734        <entry><type>text</type></entry>
1735        <entry>
1736         Return the given string suitably quoted to be used as a string literal
1737         in an <acronym>SQL</acronym> statement string; or, if the argument
1738         is null, return <literal>NULL</>.
1739         Embedded single-quotes and backslashes are properly doubled.
1740         See also <xref linkend="plpgsql-quote-literal-example">.
1741        </entry>
1742        <entry><literal>quote_nullable(NULL)</literal></entry>
1743        <entry><literal>NULL</literal></entry>
1744       </row>
1745
1746       <row>
1747        <entry><literal><function>quote_nullable(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1748        <entry><type>text</type></entry>
1749        <entry>
1750         Coerce the given value to text and then quote it as a literal;
1751         or, if the argument is null, return <literal>NULL</>.
1752         Embedded single-quotes and backslashes are properly doubled.
1753        </entry>
1754        <entry><literal>quote_nullable(42.5)</literal></entry>
1755        <entry><literal>'42.5'</literal></entry>
1756       </row>
1757
1758       <row>
1759        <entry>
1760         <indexterm>
1761          <primary>regexp_matches</primary>
1762         </indexterm>
1763         <literal><function>regexp_matches(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
1764        </entry>
1765        <entry><type>setof text[]</type></entry>
1766        <entry>
1767         Return all captured substrings resulting from matching a POSIX regular
1768         expression against the <parameter>string</parameter>. See
1769         <xref linkend="functions-posix-regexp"> for more information.
1770        </entry>
1771        <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
1772        <entry><literal>{bar,beque}</literal></entry>
1773       </row>
1774
1775       <row>
1776        <entry>
1777         <indexterm>
1778          <primary>regexp_replace</primary>
1779         </indexterm>
1780         <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>
1781        </entry>
1782        <entry><type>text</type></entry>
1783        <entry>
1784         Replace substring(s) matching a POSIX regular expression. See
1785         <xref linkend="functions-posix-regexp"> for more information.
1786        </entry>
1787        <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
1788        <entry><literal>ThM</literal></entry>
1789       </row>
1790
1791       <row>
1792        <entry>
1793         <indexterm>
1794          <primary>regexp_split_to_array</primary>
1795         </indexterm>
1796         <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>
1797        </entry>
1798        <entry><type>text[]</type></entry>
1799        <entry>
1800         Split <parameter>string</parameter> using a POSIX regular expression as
1801         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1802         information.
1803        </entry>
1804        <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
1805        <entry><literal>{hello,world}</literal></entry>
1806       </row>
1807
1808       <row>
1809        <entry>
1810         <indexterm>
1811          <primary>regexp_split_to_table</primary>
1812         </indexterm>
1813         <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>
1814        </entry>
1815        <entry><type>setof text</type></entry>
1816        <entry>
1817         Split <parameter>string</parameter> using a POSIX regular expression as
1818         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1819         information.
1820        </entry>
1821        <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
1822        <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
1823       </row>
1824
1825       <row>
1826        <entry>
1827         <indexterm>
1828          <primary>repeat</primary>
1829         </indexterm>
1830         <literal><function>repeat(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</function></literal>
1831        </entry>
1832        <entry><type>text</type></entry>
1833        <entry>Repeat <parameter>string</parameter> the specified
1834        <parameter>number</parameter> of times</entry>
1835        <entry><literal>repeat('Pg', 4)</literal></entry>
1836        <entry><literal>PgPgPgPg</literal></entry>
1837       </row>
1838
1839       <row>
1840        <entry>
1841         <indexterm>
1842          <primary>replace</primary>
1843         </indexterm>
1844         <literal><function>replace(<parameter>string</parameter> <type>text</type>,
1845         <parameter>from</parameter> <type>text</type>,
1846         <parameter>to</parameter> <type>text</type>)</function></literal>
1847        </entry>
1848        <entry><type>text</type></entry>
1849        <entry>Replace all occurrences in <parameter>string</parameter> of substring
1850         <parameter>from</parameter> with substring <parameter>to</parameter>
1851        </entry>
1852        <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
1853        <entry><literal>abXXefabXXef</literal></entry>
1854       </row>
1855
1856       <row>
1857        <entry>
1858         <indexterm>
1859          <primary>reverse</primary>
1860         </indexterm>
1861         <literal><function>reverse(<parameter>str</parameter>)</function></literal>
1862        </entry>
1863        <entry><type>text</type></entry>
1864        <entry>
1865         Return reversed string.
1866        </entry>
1867        <entry><literal>reverse('abcde')</literal></entry>
1868        <entry><literal>edcba</literal></entry>
1869       </row>
1870
1871       <row>
1872        <entry>
1873         <indexterm>
1874          <primary>right</primary>
1875         </indexterm>
1876         <literal><function>right(<parameter>str</parameter> <type>text</type>,
1877          <parameter>n</parameter> <type>int</type>)</function></literal>
1878        </entry>
1879        <entry><type>text</type></entry>
1880        <entry>
1881         Return last <replaceable>n</> characters in the string. When <replaceable>n</>
1882         is negative, return all but first |<replaceable>n</>| characters.
1883        </entry>
1884        <entry><literal>right('abcde', 2)</literal></entry>
1885        <entry><literal>de</literal></entry>
1886       </row>
1887
1888       <row>
1889        <entry>
1890         <indexterm>
1891          <primary>rpad</primary>
1892         </indexterm>
1893         <literal><function>rpad(<parameter>string</parameter> <type>text</type>,
1894         <parameter>length</parameter> <type>int</type>
1895         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1896        </entry>
1897        <entry><type>text</type></entry>
1898        <entry>
1899         Fill up the <parameter>string</parameter> to length
1900         <parameter>length</parameter> by appending the characters
1901         <parameter>fill</parameter> (a space by default).  If the
1902         <parameter>string</parameter> is already longer than
1903         <parameter>length</parameter> then it is truncated.
1904        </entry>
1905        <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
1906        <entry><literal>hixyx</literal></entry>
1907       </row>
1908
1909       <row>
1910        <entry>
1911         <indexterm>
1912          <primary>rtrim</primary>
1913         </indexterm>
1914         <literal><function>rtrim(<parameter>string</parameter> <type>text</type>
1915          <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1916        </entry>
1917        <entry><type>text</type></entry>
1918        <entry>
1919         Remove the longest string containing only characters from
1920         <parameter>characters</parameter> (a space by default) from the end of
1921         <parameter>string</parameter>
1922        </entry>
1923        <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
1924        <entry><literal>trim</literal></entry>
1925       </row>
1926
1927       <row>
1928        <entry>
1929         <indexterm>
1930          <primary>split_part</primary>
1931         </indexterm>
1932         <literal><function>split_part(<parameter>string</parameter> <type>text</type>,
1933         <parameter>delimiter</parameter> <type>text</type>,
1934         <parameter>field</parameter> <type>int</type>)</function></literal>
1935        </entry>
1936        <entry><type>text</type></entry>
1937        <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1938         and return the given field (counting from one)
1939        </entry>
1940        <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
1941        <entry><literal>def</literal></entry>
1942       </row>
1943
1944       <row>
1945        <entry>
1946         <indexterm>
1947          <primary>strpos</primary>
1948         </indexterm>
1949         <literal><function>strpos(<parameter>string</parameter>, <parameter>substring</parameter>)</function></literal>
1950        </entry>
1951        <entry><type>int</type></entry>
1952        <entry>
1953         Location of specified substring (same as
1954         <literal>position(<parameter>substring</parameter> in
1955          <parameter>string</parameter>)</literal>, but note the reversed
1956         argument order)
1957        </entry>
1958        <entry><literal>strpos('high', 'ig')</literal></entry>
1959        <entry><literal>2</literal></entry>
1960       </row>
1961
1962       <row>
1963        <entry>
1964         <indexterm>
1965          <primary>substr</primary>
1966         </indexterm>
1967         <literal><function>substr(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</function></literal>
1968        </entry>
1969        <entry><type>text</type></entry>
1970        <entry>
1971         Extract substring (same as
1972         <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
1973        </entry>
1974        <entry><literal>substr('alphabet', 3, 2)</literal></entry>
1975        <entry><literal>ph</literal></entry>
1976       </row>
1977
1978       <row>
1979        <entry>
1980         <indexterm>
1981          <primary>to_ascii</primary>
1982         </indexterm>
1983         <literal><function>to_ascii(<parameter>string</parameter> <type>text</type>
1984         <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</function></literal>
1985        </entry>
1986        <entry><type>text</type></entry>
1987        <entry>
1988        Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
1989        (only supports conversion from  <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
1990        and <literal>WIN1250</> encodings)
1991        </entry>
1992        <entry><literal>to_ascii('Karel')</literal></entry>
1993        <entry><literal>Karel</literal></entry>
1994       </row>
1995
1996       <row>
1997        <entry>
1998         <indexterm>
1999          <primary>to_hex</primary>
2000         </indexterm>
2001         <literal><function>to_hex(<parameter>number</parameter> <type>int</type>
2002         or <type>bigint</type>)</function></literal>
2003        </entry>
2004        <entry><type>text</type></entry>
2005        <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
2006         representation
2007        </entry>
2008        <entry><literal>to_hex(2147483647)</literal></entry>
2009        <entry><literal>7fffffff</literal></entry>
2010       </row>
2011
2012       <row>
2013        <entry>
2014         <indexterm>
2015          <primary>translate</primary>
2016         </indexterm>
2017         <literal><function>translate(<parameter>string</parameter> <type>text</type>,
2018         <parameter>from</parameter> <type>text</type>,
2019         <parameter>to</parameter> <type>text</type>)</function></literal>
2020        </entry>
2021        <entry><type>text</type></entry>
2022        <entry>
2023         Any character in <parameter>string</parameter> that matches a
2024         character in the <parameter>from</parameter> set is replaced by
2025         the corresponding character in the <parameter>to</parameter>
2026         set. If <parameter>from</parameter> is longer than
2027         <parameter>to</parameter>, occurrences of the extra characters in
2028         <parameter>from</parameter> are removed.
2029        </entry>
2030        <entry><literal>translate('12345', '143', 'ax')</literal></entry>
2031        <entry><literal>a2x5</literal></entry>
2032       </row>
2033
2034      </tbody>
2035     </tgroup>
2036    </table>
2037
2038    <para>
2039     The <function>concat</function>, <function>concat_ws</function> and
2040     <function>format</function> functions are variadic, so it is possible to
2041     pass the values to be concatenated or formatted as an array marked with
2042     the <literal>VARIADIC</literal> keyword (see <xref
2043     linkend="xfunc-sql-variadic-functions">).  The array's elements are
2044     treated as if they were separate ordinary arguments to the function.
2045     If the variadic array argument is NULL, <function>concat</function>
2046     and <function>concat_ws</function> return NULL, but
2047     <function>format</function> treats a NULL as a zero-element array.
2048    </para>
2049
2050    <para>
2051    See also the aggregate function <function>string_agg</function> in
2052    <xref linkend="functions-aggregate">.
2053    </para>
2054
2055    <table id="conversion-names">
2056     <title>Built-in Conversions</title>
2057     <tgroup cols="3">
2058      <thead>
2059       <row>
2060        <entry>Conversion Name
2061         <footnote>
2062          <para>
2063           The conversion names follow a standard naming scheme: The
2064           official name of the source encoding with all
2065           non-alphanumeric characters replaced by underscores, followed
2066           by <literal>_to_</literal>, followed by the similarly processed
2067           destination encoding name. Therefore, the names might deviate
2068           from the customary encoding names.
2069          </para>
2070         </footnote>
2071        </entry>
2072        <entry>Source Encoding</entry>
2073        <entry>Destination Encoding</entry>
2074       </row>
2075      </thead>
2076
2077      <tbody>
2078       <row>
2079        <entry><literal>ascii_to_mic</literal></entry>
2080        <entry><literal>SQL_ASCII</literal></entry>
2081        <entry><literal>MULE_INTERNAL</literal></entry>
2082       </row>
2083
2084       <row>
2085        <entry><literal>ascii_to_utf8</literal></entry>
2086        <entry><literal>SQL_ASCII</literal></entry>
2087        <entry><literal>UTF8</literal></entry>
2088       </row>
2089
2090       <row>
2091        <entry><literal>big5_to_euc_tw</literal></entry>
2092        <entry><literal>BIG5</literal></entry>
2093        <entry><literal>EUC_TW</literal></entry>
2094       </row>
2095
2096       <row>
2097        <entry><literal>big5_to_mic</literal></entry>
2098        <entry><literal>BIG5</literal></entry>
2099        <entry><literal>MULE_INTERNAL</literal></entry>
2100       </row>
2101
2102       <row>
2103        <entry><literal>big5_to_utf8</literal></entry>
2104        <entry><literal>BIG5</literal></entry>
2105        <entry><literal>UTF8</literal></entry>
2106       </row>
2107
2108       <row>
2109        <entry><literal>euc_cn_to_mic</literal></entry>
2110        <entry><literal>EUC_CN</literal></entry>
2111        <entry><literal>MULE_INTERNAL</literal></entry>
2112       </row>
2113
2114       <row>
2115        <entry><literal>euc_cn_to_utf8</literal></entry>
2116        <entry><literal>EUC_CN</literal></entry>
2117        <entry><literal>UTF8</literal></entry>
2118       </row>
2119
2120       <row>
2121        <entry><literal>euc_jp_to_mic</literal></entry>
2122        <entry><literal>EUC_JP</literal></entry>
2123        <entry><literal>MULE_INTERNAL</literal></entry>
2124       </row>
2125
2126       <row>
2127        <entry><literal>euc_jp_to_sjis</literal></entry>
2128        <entry><literal>EUC_JP</literal></entry>
2129        <entry><literal>SJIS</literal></entry>
2130       </row>
2131
2132       <row>
2133        <entry><literal>euc_jp_to_utf8</literal></entry>
2134        <entry><literal>EUC_JP</literal></entry>
2135        <entry><literal>UTF8</literal></entry>
2136       </row>
2137
2138       <row>
2139        <entry><literal>euc_kr_to_mic</literal></entry>
2140        <entry><literal>EUC_KR</literal></entry>
2141        <entry><literal>MULE_INTERNAL</literal></entry>
2142       </row>
2143
2144       <row>
2145        <entry><literal>euc_kr_to_utf8</literal></entry>
2146        <entry><literal>EUC_KR</literal></entry>
2147        <entry><literal>UTF8</literal></entry>
2148       </row>
2149
2150       <row>
2151        <entry><literal>euc_tw_to_big5</literal></entry>
2152        <entry><literal>EUC_TW</literal></entry>
2153        <entry><literal>BIG5</literal></entry>
2154       </row>
2155
2156       <row>
2157        <entry><literal>euc_tw_to_mic</literal></entry>
2158        <entry><literal>EUC_TW</literal></entry>
2159        <entry><literal>MULE_INTERNAL</literal></entry>
2160       </row>
2161
2162       <row>
2163        <entry><literal>euc_tw_to_utf8</literal></entry>
2164        <entry><literal>EUC_TW</literal></entry>
2165        <entry><literal>UTF8</literal></entry>
2166       </row>
2167
2168       <row>
2169        <entry><literal>gb18030_to_utf8</literal></entry>
2170        <entry><literal>GB18030</literal></entry>
2171        <entry><literal>UTF8</literal></entry>
2172       </row>
2173
2174       <row>
2175        <entry><literal>gbk_to_utf8</literal></entry>
2176        <entry><literal>GBK</literal></entry>
2177        <entry><literal>UTF8</literal></entry>
2178       </row>
2179
2180       <row>
2181        <entry><literal>iso_8859_10_to_utf8</literal></entry>
2182        <entry><literal>LATIN6</literal></entry>
2183        <entry><literal>UTF8</literal></entry>
2184       </row>
2185
2186       <row>
2187        <entry><literal>iso_8859_13_to_utf8</literal></entry>
2188        <entry><literal>LATIN7</literal></entry>
2189        <entry><literal>UTF8</literal></entry>
2190       </row>
2191
2192       <row>
2193        <entry><literal>iso_8859_14_to_utf8</literal></entry>
2194        <entry><literal>LATIN8</literal></entry>
2195        <entry><literal>UTF8</literal></entry>
2196       </row>
2197
2198       <row>
2199        <entry><literal>iso_8859_15_to_utf8</literal></entry>
2200        <entry><literal>LATIN9</literal></entry>
2201        <entry><literal>UTF8</literal></entry>
2202       </row>
2203
2204       <row>
2205        <entry><literal>iso_8859_16_to_utf8</literal></entry>
2206        <entry><literal>LATIN10</literal></entry>
2207        <entry><literal>UTF8</literal></entry>
2208       </row>
2209
2210       <row>
2211        <entry><literal>iso_8859_1_to_mic</literal></entry>
2212        <entry><literal>LATIN1</literal></entry>
2213        <entry><literal>MULE_INTERNAL</literal></entry>
2214       </row>
2215
2216       <row>
2217        <entry><literal>iso_8859_1_to_utf8</literal></entry>
2218        <entry><literal>LATIN1</literal></entry>
2219        <entry><literal>UTF8</literal></entry>
2220       </row>
2221
2222       <row>
2223        <entry><literal>iso_8859_2_to_mic</literal></entry>
2224        <entry><literal>LATIN2</literal></entry>
2225        <entry><literal>MULE_INTERNAL</literal></entry>
2226       </row>
2227
2228       <row>
2229        <entry><literal>iso_8859_2_to_utf8</literal></entry>
2230        <entry><literal>LATIN2</literal></entry>
2231        <entry><literal>UTF8</literal></entry>
2232       </row>
2233
2234       <row>
2235        <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
2236        <entry><literal>LATIN2</literal></entry>
2237        <entry><literal>WIN1250</literal></entry>
2238       </row>
2239
2240       <row>
2241        <entry><literal>iso_8859_3_to_mic</literal></entry>
2242        <entry><literal>LATIN3</literal></entry>
2243        <entry><literal>MULE_INTERNAL</literal></entry>
2244       </row>
2245
2246       <row>
2247        <entry><literal>iso_8859_3_to_utf8</literal></entry>
2248        <entry><literal>LATIN3</literal></entry>
2249        <entry><literal>UTF8</literal></entry>
2250       </row>
2251
2252       <row>
2253        <entry><literal>iso_8859_4_to_mic</literal></entry>
2254        <entry><literal>LATIN4</literal></entry>
2255        <entry><literal>MULE_INTERNAL</literal></entry>
2256       </row>
2257
2258       <row>
2259        <entry><literal>iso_8859_4_to_utf8</literal></entry>
2260        <entry><literal>LATIN4</literal></entry>
2261        <entry><literal>UTF8</literal></entry>
2262       </row>
2263
2264       <row>
2265        <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
2266        <entry><literal>ISO_8859_5</literal></entry>
2267        <entry><literal>KOI8R</literal></entry>
2268       </row>
2269
2270       <row>
2271        <entry><literal>iso_8859_5_to_mic</literal></entry>
2272        <entry><literal>ISO_8859_5</literal></entry>
2273        <entry><literal>MULE_INTERNAL</literal></entry>
2274       </row>
2275
2276       <row>
2277        <entry><literal>iso_8859_5_to_utf8</literal></entry>
2278        <entry><literal>ISO_8859_5</literal></entry>
2279        <entry><literal>UTF8</literal></entry>
2280       </row>
2281
2282       <row>
2283        <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
2284        <entry><literal>ISO_8859_5</literal></entry>
2285        <entry><literal>WIN1251</literal></entry>
2286       </row>
2287
2288       <row>
2289        <entry><literal>iso_8859_5_to_windows_866</literal></entry>
2290        <entry><literal>ISO_8859_5</literal></entry>
2291        <entry><literal>WIN866</literal></entry>
2292       </row>
2293
2294       <row>
2295        <entry><literal>iso_8859_6_to_utf8</literal></entry>
2296        <entry><literal>ISO_8859_6</literal></entry>
2297        <entry><literal>UTF8</literal></entry>
2298       </row>
2299
2300       <row>
2301        <entry><literal>iso_8859_7_to_utf8</literal></entry>
2302        <entry><literal>ISO_8859_7</literal></entry>
2303        <entry><literal>UTF8</literal></entry>
2304       </row>
2305
2306       <row>
2307        <entry><literal>iso_8859_8_to_utf8</literal></entry>
2308        <entry><literal>ISO_8859_8</literal></entry>
2309        <entry><literal>UTF8</literal></entry>
2310       </row>
2311
2312       <row>
2313        <entry><literal>iso_8859_9_to_utf8</literal></entry>
2314        <entry><literal>LATIN5</literal></entry>
2315        <entry><literal>UTF8</literal></entry>
2316       </row>
2317
2318       <row>
2319        <entry><literal>johab_to_utf8</literal></entry>
2320        <entry><literal>JOHAB</literal></entry>
2321        <entry><literal>UTF8</literal></entry>
2322       </row>
2323
2324       <row>
2325        <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
2326        <entry><literal>KOI8R</literal></entry>
2327        <entry><literal>ISO_8859_5</literal></entry>
2328       </row>
2329
2330       <row>
2331        <entry><literal>koi8_r_to_mic</literal></entry>
2332        <entry><literal>KOI8R</literal></entry>
2333        <entry><literal>MULE_INTERNAL</literal></entry>
2334       </row>
2335
2336       <row>
2337        <entry><literal>koi8_r_to_utf8</literal></entry>
2338        <entry><literal>KOI8R</literal></entry>
2339        <entry><literal>UTF8</literal></entry>
2340       </row>
2341
2342       <row>
2343        <entry><literal>koi8_r_to_windows_1251</literal></entry>
2344        <entry><literal>KOI8R</literal></entry>
2345        <entry><literal>WIN1251</literal></entry>
2346       </row>
2347
2348       <row>
2349        <entry><literal>koi8_r_to_windows_866</literal></entry>
2350        <entry><literal>KOI8R</literal></entry>
2351        <entry><literal>WIN866</literal></entry>
2352       </row>
2353
2354       <row>
2355        <entry><literal>koi8_u_to_utf8</literal></entry>
2356        <entry><literal>KOI8U</literal></entry>
2357        <entry><literal>UTF8</literal></entry>
2358       </row>
2359
2360       <row>
2361        <entry><literal>mic_to_ascii</literal></entry>
2362        <entry><literal>MULE_INTERNAL</literal></entry>
2363        <entry><literal>SQL_ASCII</literal></entry>
2364       </row>
2365
2366       <row>
2367        <entry><literal>mic_to_big5</literal></entry>
2368        <entry><literal>MULE_INTERNAL</literal></entry>
2369        <entry><literal>BIG5</literal></entry>
2370       </row>
2371
2372       <row>
2373        <entry><literal>mic_to_euc_cn</literal></entry>
2374        <entry><literal>MULE_INTERNAL</literal></entry>
2375        <entry><literal>EUC_CN</literal></entry>
2376       </row>
2377
2378       <row>
2379        <entry><literal>mic_to_euc_jp</literal></entry>
2380        <entry><literal>MULE_INTERNAL</literal></entry>
2381        <entry><literal>EUC_JP</literal></entry>
2382       </row>
2383
2384       <row>
2385        <entry><literal>mic_to_euc_kr</literal></entry>
2386        <entry><literal>MULE_INTERNAL</literal></entry>
2387        <entry><literal>EUC_KR</literal></entry>
2388       </row>
2389
2390       <row>
2391        <entry><literal>mic_to_euc_tw</literal></entry>
2392        <entry><literal>MULE_INTERNAL</literal></entry>
2393        <entry><literal>EUC_TW</literal></entry>
2394       </row>
2395
2396       <row>
2397        <entry><literal>mic_to_iso_8859_1</literal></entry>
2398        <entry><literal>MULE_INTERNAL</literal></entry>
2399        <entry><literal>LATIN1</literal></entry>
2400       </row>
2401
2402       <row>
2403        <entry><literal>mic_to_iso_8859_2</literal></entry>
2404        <entry><literal>MULE_INTERNAL</literal></entry>
2405        <entry><literal>LATIN2</literal></entry>
2406       </row>
2407
2408       <row>
2409        <entry><literal>mic_to_iso_8859_3</literal></entry>
2410        <entry><literal>MULE_INTERNAL</literal></entry>
2411        <entry><literal>LATIN3</literal></entry>
2412       </row>
2413
2414       <row>
2415        <entry><literal>mic_to_iso_8859_4</literal></entry>
2416        <entry><literal>MULE_INTERNAL</literal></entry>
2417        <entry><literal>LATIN4</literal></entry>
2418       </row>
2419
2420       <row>
2421        <entry><literal>mic_to_iso_8859_5</literal></entry>
2422        <entry><literal>MULE_INTERNAL</literal></entry>
2423        <entry><literal>ISO_8859_5</literal></entry>
2424       </row>
2425
2426       <row>
2427        <entry><literal>mic_to_koi8_r</literal></entry>
2428        <entry><literal>MULE_INTERNAL</literal></entry>
2429        <entry><literal>KOI8R</literal></entry>
2430       </row>
2431
2432       <row>
2433        <entry><literal>mic_to_sjis</literal></entry>
2434        <entry><literal>MULE_INTERNAL</literal></entry>
2435        <entry><literal>SJIS</literal></entry>
2436       </row>
2437
2438       <row>
2439        <entry><literal>mic_to_windows_1250</literal></entry>
2440        <entry><literal>MULE_INTERNAL</literal></entry>
2441        <entry><literal>WIN1250</literal></entry>
2442       </row>
2443
2444       <row>
2445        <entry><literal>mic_to_windows_1251</literal></entry>
2446        <entry><literal>MULE_INTERNAL</literal></entry>
2447        <entry><literal>WIN1251</literal></entry>
2448       </row>
2449
2450       <row>
2451        <entry><literal>mic_to_windows_866</literal></entry>
2452        <entry><literal>MULE_INTERNAL</literal></entry>
2453        <entry><literal>WIN866</literal></entry>
2454       </row>
2455
2456       <row>
2457        <entry><literal>sjis_to_euc_jp</literal></entry>
2458        <entry><literal>SJIS</literal></entry>
2459        <entry><literal>EUC_JP</literal></entry>
2460       </row>
2461
2462       <row>
2463        <entry><literal>sjis_to_mic</literal></entry>
2464        <entry><literal>SJIS</literal></entry>
2465        <entry><literal>MULE_INTERNAL</literal></entry>
2466       </row>
2467
2468       <row>
2469        <entry><literal>sjis_to_utf8</literal></entry>
2470        <entry><literal>SJIS</literal></entry>
2471        <entry><literal>UTF8</literal></entry>
2472       </row>
2473
2474       <row>
2475        <entry><literal>tcvn_to_utf8</literal></entry>
2476        <entry><literal>WIN1258</literal></entry>
2477        <entry><literal>UTF8</literal></entry>
2478       </row>
2479
2480       <row>
2481        <entry><literal>uhc_to_utf8</literal></entry>
2482        <entry><literal>UHC</literal></entry>
2483        <entry><literal>UTF8</literal></entry>
2484       </row>
2485
2486       <row>
2487        <entry><literal>utf8_to_ascii</literal></entry>
2488        <entry><literal>UTF8</literal></entry>
2489        <entry><literal>SQL_ASCII</literal></entry>
2490       </row>
2491
2492       <row>
2493        <entry><literal>utf8_to_big5</literal></entry>
2494        <entry><literal>UTF8</literal></entry>
2495        <entry><literal>BIG5</literal></entry>
2496       </row>
2497
2498       <row>
2499        <entry><literal>utf8_to_euc_cn</literal></entry>
2500        <entry><literal>UTF8</literal></entry>
2501        <entry><literal>EUC_CN</literal></entry>
2502       </row>
2503
2504       <row>
2505        <entry><literal>utf8_to_euc_jp</literal></entry>
2506        <entry><literal>UTF8</literal></entry>
2507        <entry><literal>EUC_JP</literal></entry>
2508       </row>
2509
2510       <row>
2511        <entry><literal>utf8_to_euc_kr</literal></entry>
2512        <entry><literal>UTF8</literal></entry>
2513        <entry><literal>EUC_KR</literal></entry>
2514       </row>
2515
2516       <row>
2517        <entry><literal>utf8_to_euc_tw</literal></entry>
2518        <entry><literal>UTF8</literal></entry>
2519        <entry><literal>EUC_TW</literal></entry>
2520       </row>
2521
2522       <row>
2523        <entry><literal>utf8_to_gb18030</literal></entry>
2524        <entry><literal>UTF8</literal></entry>
2525        <entry><literal>GB18030</literal></entry>
2526       </row>
2527
2528       <row>
2529        <entry><literal>utf8_to_gbk</literal></entry>
2530        <entry><literal>UTF8</literal></entry>
2531        <entry><literal>GBK</literal></entry>
2532       </row>
2533
2534       <row>
2535        <entry><literal>utf8_to_iso_8859_1</literal></entry>
2536        <entry><literal>UTF8</literal></entry>
2537        <entry><literal>LATIN1</literal></entry>
2538       </row>
2539
2540       <row>
2541        <entry><literal>utf8_to_iso_8859_10</literal></entry>
2542        <entry><literal>UTF8</literal></entry>
2543        <entry><literal>LATIN6</literal></entry>
2544       </row>
2545
2546       <row>
2547        <entry><literal>utf8_to_iso_8859_13</literal></entry>
2548        <entry><literal>UTF8</literal></entry>
2549        <entry><literal>LATIN7</literal></entry>
2550       </row>
2551
2552       <row>
2553        <entry><literal>utf8_to_iso_8859_14</literal></entry>
2554        <entry><literal>UTF8</literal></entry>
2555        <entry><literal>LATIN8</literal></entry>
2556       </row>
2557
2558       <row>
2559        <entry><literal>utf8_to_iso_8859_15</literal></entry>
2560        <entry><literal>UTF8</literal></entry>
2561        <entry><literal>LATIN9</literal></entry>
2562       </row>
2563
2564       <row>
2565        <entry><literal>utf8_to_iso_8859_16</literal></entry>
2566        <entry><literal>UTF8</literal></entry>
2567        <entry><literal>LATIN10</literal></entry>
2568       </row>
2569
2570       <row>
2571        <entry><literal>utf8_to_iso_8859_2</literal></entry>
2572        <entry><literal>UTF8</literal></entry>
2573        <entry><literal>LATIN2</literal></entry>
2574       </row>
2575
2576       <row>
2577        <entry><literal>utf8_to_iso_8859_3</literal></entry>
2578        <entry><literal>UTF8</literal></entry>
2579        <entry><literal>LATIN3</literal></entry>
2580       </row>
2581
2582       <row>
2583        <entry><literal>utf8_to_iso_8859_4</literal></entry>
2584        <entry><literal>UTF8</literal></entry>
2585        <entry><literal>LATIN4</literal></entry>
2586       </row>
2587
2588       <row>
2589        <entry><literal>utf8_to_iso_8859_5</literal></entry>
2590        <entry><literal>UTF8</literal></entry>
2591        <entry><literal>ISO_8859_5</literal></entry>
2592       </row>
2593
2594       <row>
2595        <entry><literal>utf8_to_iso_8859_6</literal></entry>
2596        <entry><literal>UTF8</literal></entry>
2597        <entry><literal>ISO_8859_6</literal></entry>
2598       </row>
2599
2600       <row>
2601        <entry><literal>utf8_to_iso_8859_7</literal></entry>
2602        <entry><literal>UTF8</literal></entry>
2603        <entry><literal>ISO_8859_7</literal></entry>
2604       </row>
2605
2606       <row>
2607        <entry><literal>utf8_to_iso_8859_8</literal></entry>
2608        <entry><literal>UTF8</literal></entry>
2609        <entry><literal>ISO_8859_8</literal></entry>
2610       </row>
2611
2612       <row>
2613        <entry><literal>utf8_to_iso_8859_9</literal></entry>
2614        <entry><literal>UTF8</literal></entry>
2615        <entry><literal>LATIN5</literal></entry>
2616       </row>
2617
2618       <row>
2619        <entry><literal>utf8_to_johab</literal></entry>
2620        <entry><literal>UTF8</literal></entry>
2621        <entry><literal>JOHAB</literal></entry>
2622       </row>
2623
2624       <row>
2625        <entry><literal>utf8_to_koi8_r</literal></entry>
2626        <entry><literal>UTF8</literal></entry>
2627        <entry><literal>KOI8R</literal></entry>
2628       </row>
2629
2630       <row>
2631        <entry><literal>utf8_to_koi8_u</literal></entry>
2632        <entry><literal>UTF8</literal></entry>
2633        <entry><literal>KOI8U</literal></entry>
2634       </row>
2635
2636       <row>
2637        <entry><literal>utf8_to_sjis</literal></entry>
2638        <entry><literal>UTF8</literal></entry>
2639        <entry><literal>SJIS</literal></entry>
2640       </row>
2641
2642       <row>
2643        <entry><literal>utf8_to_tcvn</literal></entry>
2644        <entry><literal>UTF8</literal></entry>
2645        <entry><literal>WIN1258</literal></entry>
2646       </row>
2647
2648       <row>
2649        <entry><literal>utf8_to_uhc</literal></entry>
2650        <entry><literal>UTF8</literal></entry>
2651        <entry><literal>UHC</literal></entry>
2652       </row>
2653
2654       <row>
2655        <entry><literal>utf8_to_windows_1250</literal></entry>
2656        <entry><literal>UTF8</literal></entry>
2657        <entry><literal>WIN1250</literal></entry>
2658       </row>
2659
2660       <row>
2661        <entry><literal>utf8_to_windows_1251</literal></entry>
2662        <entry><literal>UTF8</literal></entry>
2663        <entry><literal>WIN1251</literal></entry>
2664       </row>
2665
2666       <row>
2667        <entry><literal>utf8_to_windows_1252</literal></entry>
2668        <entry><literal>UTF8</literal></entry>
2669        <entry><literal>WIN1252</literal></entry>
2670       </row>
2671
2672       <row>
2673        <entry><literal>utf8_to_windows_1253</literal></entry>
2674        <entry><literal>UTF8</literal></entry>
2675        <entry><literal>WIN1253</literal></entry>
2676       </row>
2677
2678       <row>
2679        <entry><literal>utf8_to_windows_1254</literal></entry>
2680        <entry><literal>UTF8</literal></entry>
2681        <entry><literal>WIN1254</literal></entry>
2682       </row>
2683
2684       <row>
2685        <entry><literal>utf8_to_windows_1255</literal></entry>
2686        <entry><literal>UTF8</literal></entry>
2687        <entry><literal>WIN1255</literal></entry>
2688       </row>
2689
2690       <row>
2691        <entry><literal>utf8_to_windows_1256</literal></entry>
2692        <entry><literal>UTF8</literal></entry>
2693        <entry><literal>WIN1256</literal></entry>
2694       </row>
2695
2696       <row>
2697        <entry><literal>utf8_to_windows_1257</literal></entry>
2698        <entry><literal>UTF8</literal></entry>
2699        <entry><literal>WIN1257</literal></entry>
2700       </row>
2701
2702       <row>
2703        <entry><literal>utf8_to_windows_866</literal></entry>
2704        <entry><literal>UTF8</literal></entry>
2705        <entry><literal>WIN866</literal></entry>
2706       </row>
2707
2708       <row>
2709        <entry><literal>utf8_to_windows_874</literal></entry>
2710        <entry><literal>UTF8</literal></entry>
2711        <entry><literal>WIN874</literal></entry>
2712       </row>
2713
2714       <row>
2715        <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
2716        <entry><literal>WIN1250</literal></entry>
2717        <entry><literal>LATIN2</literal></entry>
2718       </row>
2719
2720       <row>
2721        <entry><literal>windows_1250_to_mic</literal></entry>
2722        <entry><literal>WIN1250</literal></entry>
2723        <entry><literal>MULE_INTERNAL</literal></entry>
2724       </row>
2725
2726       <row>
2727        <entry><literal>windows_1250_to_utf8</literal></entry>
2728        <entry><literal>WIN1250</literal></entry>
2729        <entry><literal>UTF8</literal></entry>
2730       </row>
2731
2732       <row>
2733        <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
2734        <entry><literal>WIN1251</literal></entry>
2735        <entry><literal>ISO_8859_5</literal></entry>
2736       </row>
2737
2738       <row>
2739        <entry><literal>windows_1251_to_koi8_r</literal></entry>
2740        <entry><literal>WIN1251</literal></entry>
2741        <entry><literal>KOI8R</literal></entry>
2742       </row>
2743
2744       <row>
2745        <entry><literal>windows_1251_to_mic</literal></entry>
2746        <entry><literal>WIN1251</literal></entry>
2747        <entry><literal>MULE_INTERNAL</literal></entry>
2748       </row>
2749
2750       <row>
2751        <entry><literal>windows_1251_to_utf8</literal></entry>
2752        <entry><literal>WIN1251</literal></entry>
2753        <entry><literal>UTF8</literal></entry>
2754       </row>
2755
2756       <row>
2757        <entry><literal>windows_1251_to_windows_866</literal></entry>
2758        <entry><literal>WIN1251</literal></entry>
2759        <entry><literal>WIN866</literal></entry>
2760       </row>
2761
2762       <row>
2763        <entry><literal>windows_1252_to_utf8</literal></entry>
2764        <entry><literal>WIN1252</literal></entry>
2765        <entry><literal>UTF8</literal></entry>
2766       </row>
2767
2768       <row>
2769        <entry><literal>windows_1256_to_utf8</literal></entry>
2770        <entry><literal>WIN1256</literal></entry>
2771        <entry><literal>UTF8</literal></entry>
2772       </row>
2773
2774       <row>
2775        <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2776        <entry><literal>WIN866</literal></entry>
2777        <entry><literal>ISO_8859_5</literal></entry>
2778       </row>
2779
2780       <row>
2781        <entry><literal>windows_866_to_koi8_r</literal></entry>
2782        <entry><literal>WIN866</literal></entry>
2783        <entry><literal>KOI8R</literal></entry>
2784       </row>
2785
2786       <row>
2787        <entry><literal>windows_866_to_mic</literal></entry>
2788        <entry><literal>WIN866</literal></entry>
2789        <entry><literal>MULE_INTERNAL</literal></entry>
2790       </row>
2791
2792       <row>
2793        <entry><literal>windows_866_to_utf8</literal></entry>
2794        <entry><literal>WIN866</literal></entry>
2795        <entry><literal>UTF8</literal></entry>
2796       </row>
2797
2798       <row>
2799        <entry><literal>windows_866_to_windows_1251</literal></entry>
2800        <entry><literal>WIN866</literal></entry>
2801        <entry><literal>WIN</literal></entry>
2802       </row>
2803
2804       <row>
2805        <entry><literal>windows_874_to_utf8</literal></entry>
2806        <entry><literal>WIN874</literal></entry>
2807        <entry><literal>UTF8</literal></entry>
2808       </row>
2809
2810       <row>
2811        <entry><literal>euc_jis_2004_to_utf8</literal></entry>
2812        <entry><literal>EUC_JIS_2004</literal></entry>
2813        <entry><literal>UTF8</literal></entry>
2814       </row>
2815
2816       <row>
2817        <entry><literal>ut8_to_euc_jis_2004</literal></entry>
2818        <entry><literal>UTF8</literal></entry>
2819        <entry><literal>EUC_JIS_2004</literal></entry>
2820       </row>
2821
2822       <row>
2823        <entry><literal>shift_jis_2004_to_utf8</literal></entry>
2824        <entry><literal>SHIFT_JIS_2004</literal></entry>
2825        <entry><literal>UTF8</literal></entry>
2826       </row>
2827
2828       <row>
2829        <entry><literal>ut8_to_shift_jis_2004</literal></entry>
2830        <entry><literal>UTF8</literal></entry>
2831        <entry><literal>SHIFT_JIS_2004</literal></entry>
2832       </row>
2833
2834       <row>
2835        <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
2836        <entry><literal>EUC_JIS_2004</literal></entry>
2837        <entry><literal>SHIFT_JIS_2004</literal></entry>
2838       </row>
2839
2840       <row>
2841        <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
2842        <entry><literal>SHIFT_JIS_2004</literal></entry>
2843        <entry><literal>EUC_JIS_2004</literal></entry>
2844       </row>
2845
2846      </tbody>
2847     </tgroup>
2848    </table>
2849
2850   </sect1>
2851
2852
2853   <sect1 id="functions-binarystring">
2854    <title>Binary String Functions and Operators</title>
2855
2856    <indexterm zone="functions-binarystring">
2857     <primary>binary data</primary>
2858     <secondary>functions</secondary>
2859    </indexterm>
2860
2861    <para>
2862     This section describes functions and operators for examining and
2863     manipulating values of type <type>bytea</type>.
2864    </para>
2865
2866    <para>
2867     <acronym>SQL</acronym> defines some string functions that use
2868     key words, rather than commas, to separate
2869     arguments.  Details are in
2870     <xref linkend="functions-binarystring-sql">.
2871     <productname>PostgreSQL</> also provides versions of these functions
2872     that use the regular function invocation syntax
2873     (see <xref linkend="functions-binarystring-other">).
2874    </para>
2875
2876    <note>
2877     <para>
2878      The sample results shown on this page assume that the server parameter
2879      <link linkend="guc-bytea-output"><varname>bytea_output</></link> is set
2880      to <literal>escape</literal> (the traditional PostgreSQL format).
2881     </para>
2882    </note>
2883
2884    <table id="functions-binarystring-sql">
2885     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
2886     <tgroup cols="5">
2887      <thead>
2888       <row>
2889        <entry>Function</entry>
2890        <entry>Return Type</entry>
2891        <entry>Description</entry>
2892        <entry>Example</entry>
2893        <entry>Result</entry>
2894       </row>
2895      </thead>
2896
2897      <tbody>
2898       <row>
2899        <entry><literal><parameter>string</parameter> <literal>||</literal>
2900         <parameter>string</parameter></literal></entry>
2901        <entry> <type>bytea</type> </entry>
2902        <entry>
2903         String concatenation
2904         <indexterm>
2905          <primary>binary string</primary>
2906          <secondary>concatenation</secondary>
2907         </indexterm>
2908        </entry>
2909        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
2910        <entry><literal>\\Post'gres\000</literal></entry>
2911       </row>
2912
2913       <row>
2914        <entry>
2915         <indexterm>
2916          <primary>octet_length</primary>
2917         </indexterm>
2918         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
2919        </entry>
2920        <entry><type>int</type></entry>
2921        <entry>Number of bytes in binary string</entry>
2922        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
2923        <entry><literal>5</literal></entry>
2924       </row>
2925
2926       <row>
2927        <entry>
2928         <indexterm>
2929          <primary>overlay</primary>
2930         </indexterm>
2931         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
2932        </entry>
2933        <entry><type>bytea</type></entry>
2934        <entry>
2935         Replace substring
2936        </entry>
2937        <entry><literal>overlay(E'Th\\000omas'::bytea placing E'\\002\\003'::bytea from 2 for 3)</literal></entry>
2938        <entry><literal>T\\002\\003mas</literal></entry>
2939       </row>
2940
2941       <row>
2942        <entry>
2943         <indexterm>
2944          <primary>position</primary>
2945         </indexterm>
2946         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
2947        </entry>
2948        <entry><type>int</type></entry>
2949        <entry>Location of specified substring</entry>
2950       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
2951        <entry><literal>3</literal></entry>
2952       </row>
2953
2954       <row>
2955        <entry>
2956         <indexterm>
2957          <primary>substring</primary>
2958         </indexterm>
2959         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
2960        </entry>
2961        <entry><type>bytea</type></entry>
2962        <entry>
2963         Extract substring
2964        </entry>
2965        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
2966        <entry><literal>h\000o</literal></entry>
2967       </row>
2968
2969       <row>
2970        <entry>
2971         <indexterm>
2972          <primary>trim</primary>
2973         </indexterm>
2974         <literal><function>trim(<optional>both</optional>
2975         <parameter>bytes</parameter> from
2976         <parameter>string</parameter>)</function></literal>
2977        </entry>
2978        <entry><type>bytea</type></entry>
2979        <entry>
2980         Remove the longest string containing only the bytes in
2981         <parameter>bytes</parameter> from the start
2982         and end of <parameter>string</parameter>
2983        </entry>
2984        <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
2985        <entry><literal>Tom</literal></entry>
2986       </row>
2987      </tbody>
2988     </tgroup>
2989    </table>
2990
2991    <para>
2992     Additional binary string manipulation functions are available and
2993     are listed in <xref linkend="functions-binarystring-other">.  Some
2994     of them are used internally to implement the
2995     <acronym>SQL</acronym>-standard string functions listed in <xref
2996     linkend="functions-binarystring-sql">.
2997    </para>
2998
2999    <table id="functions-binarystring-other">
3000     <title>Other Binary String Functions</title>
3001     <tgroup cols="5">
3002      <thead>
3003       <row>
3004        <entry>Function</entry>
3005        <entry>Return Type</entry>
3006        <entry>Description</entry>
3007        <entry>Example</entry>
3008        <entry>Result</entry>
3009       </row>
3010      </thead>
3011
3012      <tbody>
3013       <row>
3014        <entry>
3015         <indexterm>
3016          <primary>btrim</primary>
3017         </indexterm>
3018         <literal><function>btrim(<parameter>string</parameter>
3019         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</function></literal>
3020        </entry>
3021        <entry><type>bytea</type></entry>
3022        <entry>
3023         Remove the longest string consisting only of bytes
3024         in <parameter>bytes</parameter> from the start and end of
3025         <parameter>string</parameter>
3026       </entry>
3027       <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
3028       <entry><literal>trim</literal></entry>
3029      </row>
3030
3031      <row>
3032       <entry>
3033         <indexterm>
3034          <primary>decode</primary>
3035         </indexterm>
3036        <literal><function>decode(<parameter>string</parameter> <type>text</type>,
3037               <parameter>type</parameter> <type>text</type>)</function></literal>
3038       </entry>
3039       <entry><type>bytea</type></entry>
3040       <entry>
3041        Decode binary string from <parameter>string</parameter> previously
3042        encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
3043       </entry>
3044       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
3045       <entry><literal>123\000456</literal></entry>
3046      </row>
3047
3048      <row>
3049       <entry>
3050         <indexterm>
3051          <primary>encode</primary>
3052         </indexterm>
3053        <literal><function>encode(<parameter>string</parameter> <type>bytea</type>,
3054               <parameter>type</parameter> <type>text</type>)</function></literal>
3055       </entry>
3056       <entry><type>text</type></entry>
3057       <entry>
3058        Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
3059        types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
3060       </entry>
3061       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
3062       <entry><literal>123\000456</literal></entry>
3063      </row>
3064
3065       <row>
3066        <entry>
3067         <indexterm>
3068          <primary>get_bit</primary>
3069         </indexterm>
3070         <literal><function>get_bit(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3071        </entry>
3072        <entry><type>int</type></entry>
3073        <entry>
3074         Extract bit from string
3075        </entry>
3076        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
3077        <entry><literal>1</literal></entry>
3078       </row>
3079
3080       <row>
3081        <entry>
3082         <indexterm>
3083          <primary>get_byte</primary>
3084         </indexterm>
3085         <literal><function>get_byte(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3086        </entry>
3087        <entry><type>int</type></entry>
3088        <entry>
3089         Extract byte from string
3090        </entry>
3091        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
3092        <entry><literal>109</literal></entry>
3093       </row>
3094
3095      <row>
3096       <entry>
3097        <indexterm>
3098         <primary>length</primary>
3099        </indexterm>
3100        <literal><function>length(<parameter>string</parameter>)</function></literal>
3101       </entry>
3102       <entry><type>int</type></entry>
3103       <entry>
3104        Length of binary string
3105        <indexterm>
3106         <primary>binary string</primary>
3107         <secondary>length</secondary>
3108        </indexterm>
3109        <indexterm>
3110         <primary>length</primary>
3111         <secondary sortas="binary string">of a binary string</secondary>
3112         <see>binary strings, length</see>
3113        </indexterm>
3114       </entry>
3115       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
3116       <entry><literal>5</literal></entry>
3117      </row>
3118
3119      <row>
3120       <entry>
3121        <indexterm>
3122         <primary>md5</primary>
3123        </indexterm>
3124        <literal><function>md5(<parameter>string</parameter>)</function></literal>
3125       </entry>
3126       <entry><type>text</type></entry>
3127       <entry>
3128        Calculates the MD5 hash of <parameter>string</parameter>,
3129        returning the result in hexadecimal
3130       </entry>
3131       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
3132       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
3133      </row>
3134
3135       <row>
3136        <entry>
3137         <indexterm>
3138          <primary>set_bit</primary>
3139         </indexterm>
3140         <literal><function>set_bit(<parameter>string</parameter>,
3141         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3142        </entry>
3143        <entry><type>bytea</type></entry>
3144        <entry>
3145         Set bit in string
3146        </entry>
3147        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
3148        <entry><literal>Th\000omAs</literal></entry>
3149       </row>
3150
3151       <row>
3152        <entry>
3153         <indexterm>
3154          <primary>set_byte</primary>
3155         </indexterm>
3156         <literal><function>set_byte(<parameter>string</parameter>,
3157         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3158        </entry>
3159        <entry><type>bytea</type></entry>
3160        <entry>
3161         Set byte in string
3162        </entry>
3163        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
3164        <entry><literal>Th\000o@as</literal></entry>
3165       </row>
3166     </tbody>
3167    </tgroup>
3168   </table>
3169
3170   <para>
3171    <function>get_byte</> and <function>set_byte</> number the first byte
3172    of a binary string as byte 0.
3173    <function>get_bit</> and <function>set_bit</> number bits from the
3174    right within each byte; for example bit 0 is the least significant bit of
3175    the first byte, and bit 15 is the most significant bit of the second byte.
3176   </para>
3177
3178   <para>
3179    See also the aggregate function <function>string_agg</function> in
3180    <xref linkend="functions-aggregate">.
3181   </para>
3182  </sect1>
3183
3184
3185   <sect1 id="functions-bitstring">
3186    <title>Bit String Functions and Operators</title>
3187
3188    <indexterm zone="functions-bitstring">
3189     <primary>bit strings</primary>
3190     <secondary>functions</secondary>
3191    </indexterm>
3192
3193    <para>
3194     This section describes functions and operators for examining and
3195     manipulating bit strings, that is values of the types
3196     <type>bit</type> and <type>bit varying</type>.  Aside from the
3197     usual comparison operators, the operators
3198     shown in <xref linkend="functions-bit-string-op-table"> can be used.
3199     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
3200     and <literal>#</literal> must be of equal length.  When bit
3201     shifting, the original length of the string is preserved, as shown
3202     in the examples.
3203    </para>
3204
3205    <table id="functions-bit-string-op-table">
3206     <title>Bit String Operators</title>
3207
3208     <tgroup cols="4">
3209      <thead>
3210       <row>
3211        <entry>Operator</entry>
3212        <entry>Description</entry>
3213        <entry>Example</entry>
3214        <entry>Result</entry>
3215       </row>
3216      </thead>
3217
3218      <tbody>
3219       <row>
3220        <entry> <literal>||</literal> </entry>
3221        <entry>concatenation</entry>
3222        <entry><literal>B'10001' || B'011'</literal></entry>
3223        <entry><literal>10001011</literal></entry>
3224       </row>
3225
3226       <row>
3227        <entry> <literal>&amp;</literal> </entry>
3228        <entry>bitwise AND</entry>
3229        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
3230        <entry><literal>00001</literal></entry>
3231       </row>
3232
3233       <row>
3234        <entry> <literal>|</literal> </entry>
3235        <entry>bitwise OR</entry>
3236        <entry><literal>B'10001' | B'01101'</literal></entry>
3237        <entry><literal>11101</literal></entry>
3238       </row>
3239
3240       <row>
3241        <entry> <literal>#</literal> </entry>
3242        <entry>bitwise XOR</entry>
3243        <entry><literal>B'10001' # B'01101'</literal></entry>
3244        <entry><literal>11100</literal></entry>
3245       </row>
3246
3247       <row>
3248        <entry> <literal>~</literal> </entry>
3249        <entry>bitwise NOT</entry>
3250        <entry><literal>~ B'10001'</literal></entry>
3251        <entry><literal>01110</literal></entry>
3252       </row>
3253
3254       <row>
3255        <entry> <literal>&lt;&lt;</literal> </entry>
3256        <entry>bitwise shift left</entry>
3257        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
3258        <entry><literal>01000</literal></entry>
3259       </row>
3260
3261       <row>
3262        <entry> <literal>&gt;&gt;</literal> </entry>
3263        <entry>bitwise shift right</entry>
3264        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
3265        <entry><literal>00100</literal></entry>
3266       </row>
3267      </tbody>
3268     </tgroup>
3269    </table>
3270
3271    <para>
3272     The following <acronym>SQL</acronym>-standard functions work on bit
3273     strings as well as character strings:
3274     <literal><function>length</function></literal>,
3275     <literal><function>bit_length</function></literal>,
3276     <literal><function>octet_length</function></literal>,
3277     <literal><function>position</function></literal>,
3278     <literal><function>substring</function></literal>,
3279     <literal><function>overlay</function></literal>.
3280    </para>
3281
3282    <para>
3283     The following functions work on bit strings as well as binary
3284     strings:
3285     <literal><function>get_bit</function></literal>,
3286     <literal><function>set_bit</function></literal>.
3287     When working with a bit string, these functions number the first
3288     (leftmost) bit of the string as bit 0.
3289    </para>
3290
3291    <para>
3292     In addition, it is possible to cast integral values to and from type
3293     <type>bit</>.
3294     Some examples:
3295 <programlisting>
3296 44::bit(10)                    <lineannotation>0000101100</lineannotation>
3297 44::bit(3)                     <lineannotation>100</lineannotation>
3298 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
3299 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
3300 </programlisting>
3301     Note that casting to just <quote>bit</> means casting to
3302     <literal>bit(1)</>, and so will deliver only the least significant
3303     bit of the integer.
3304    </para>
3305
3306     <note>
3307      <para>
3308       Prior to <productname>PostgreSQL</productname> 8.0, casting an
3309       integer to <type>bit(n)</> would copy the leftmost <literal>n</>
3310       bits of the integer, whereas now it copies the rightmost <literal>n</>
3311       bits.  Also, casting an integer to a bit string width wider than
3312       the integer itself will sign-extend on the left.
3313      </para>
3314     </note>
3315
3316   </sect1>
3317
3318
3319  <sect1 id="functions-matching">
3320   <title>Pattern Matching</title>
3321
3322   <indexterm zone="functions-matching">
3323    <primary>pattern matching</primary>
3324   </indexterm>
3325
3326    <para>
3327     There are three separate approaches to pattern matching provided
3328     by <productname>PostgreSQL</productname>: the traditional
3329     <acronym>SQL</acronym> <function>LIKE</function> operator, the
3330     more recent <function>SIMILAR TO</function> operator (added in
3331     SQL:1999), and <acronym>POSIX</acronym>-style regular
3332     expressions.  Aside from the basic <quote>does this string match
3333     this pattern?</> operators, functions are available to extract
3334     or replace matching substrings and to split a string at matching
3335     locations.
3336    </para>
3337
3338    <tip>
3339     <para>
3340      If you have pattern matching needs that go beyond this,
3341      consider writing a user-defined function in Perl or Tcl.
3342     </para>
3343    </tip>
3344
3345   <sect2 id="functions-like">
3346    <title><function>LIKE</function></title>
3347
3348    <indexterm>
3349     <primary>LIKE</primary>
3350    </indexterm>
3351
3352 <synopsis>
3353 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3354 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3355 </synopsis>
3356
3357     <para>
3358      The <function>LIKE</function> expression returns true if the
3359      <replaceable>string</replaceable> matches the supplied
3360      <replaceable>pattern</replaceable>.  (As
3361      expected, the <function>NOT LIKE</function> expression returns
3362      false if <function>LIKE</function> returns true, and vice versa.
3363      An equivalent expression is
3364      <literal>NOT (<replaceable>string</replaceable> LIKE
3365       <replaceable>pattern</replaceable>)</literal>.)
3366     </para>
3367
3368     <para>
3369      If <replaceable>pattern</replaceable> does not contain percent
3370      signs or underscores, then the pattern only represents the string
3371      itself; in that case <function>LIKE</function> acts like the
3372      equals operator.  An underscore (<literal>_</literal>) in
3373      <replaceable>pattern</replaceable> stands for (matches) any single
3374      character; a percent sign (<literal>%</literal>) matches any sequence
3375      of zero or more characters.
3376     </para>
3377
3378    <para>
3379     Some examples:
3380 <programlisting>
3381 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
3382 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
3383 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
3384 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
3385 </programlisting>
3386    </para>
3387
3388    <para>
3389     <function>LIKE</function> pattern matching always covers the entire
3390     string.  Therefore, if it's desired to match a sequence anywhere within
3391     a string, the pattern must start and end with a percent sign.
3392    </para>
3393
3394    <para>
3395     To match a literal underscore or percent sign without matching
3396     other characters, the respective character in
3397     <replaceable>pattern</replaceable> must be
3398     preceded by the escape character.  The default escape
3399     character is the backslash but a different one can be selected by
3400     using the <literal>ESCAPE</literal> clause.  To match the escape
3401     character itself, write two escape characters.
3402    </para>
3403
3404    <note>
3405     <para>
3406      If you have <xref linkend="guc-standard-conforming-strings"> turned off,
3407      any backslashes you write in literal string constants will need to be
3408      doubled.  See <xref linkend="sql-syntax-strings"> for more information.
3409     </para>
3410    </note>
3411
3412    <para>
3413     It's also possible to select no escape character by writing
3414     <literal>ESCAPE ''</literal>.  This effectively disables the
3415     escape mechanism, which makes it impossible to turn off the
3416     special meaning of underscore and percent signs in the pattern.
3417    </para>
3418
3419    <para>
3420     The key word <token>ILIKE</token> can be used instead of
3421     <token>LIKE</token> to make the match case-insensitive according
3422     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3423     <productname>PostgreSQL</productname> extension.
3424    </para>
3425
3426    <para>
3427     The operator <literal>~~</literal> is equivalent to
3428     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3429     <function>ILIKE</function>.  There are also
3430     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3431     represent <function>NOT LIKE</function> and <function>NOT
3432     ILIKE</function>, respectively.  All of these operators are
3433     <productname>PostgreSQL</productname>-specific.
3434    </para>
3435   </sect2>
3436
3437
3438   <sect2 id="functions-similarto-regexp">
3439    <title><function>SIMILAR TO</function> Regular Expressions</title>
3440
3441    <indexterm>
3442     <primary>regular expression</primary>
3443     <!-- <seealso>pattern matching</seealso> breaks index build -->
3444    </indexterm>
3445
3446    <indexterm>
3447     <primary>SIMILAR TO</primary>
3448    </indexterm>
3449    <indexterm>
3450     <primary>substring</primary>
3451    </indexterm>
3452
3453 <synopsis>
3454 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3455 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3456 </synopsis>
3457
3458    <para>
3459     The <function>SIMILAR TO</function> operator returns true or
3460     false depending on whether its pattern matches the given string.
3461     It is similar to <function>LIKE</function>, except that it
3462     interprets the pattern using the SQL standard's definition of a
3463     regular expression.  SQL regular expressions are a curious cross
3464     between <function>LIKE</function> notation and common regular
3465     expression notation.
3466    </para>
3467
3468    <para>
3469     Like <function>LIKE</function>, the <function>SIMILAR TO</function>
3470     operator succeeds only if its pattern matches the entire string;
3471     this is unlike common regular expression behavior where the pattern
3472     can match any part of the string.
3473     Also like
3474     <function>LIKE</function>, <function>SIMILAR TO</function> uses
3475     <literal>_</> and <literal>%</> as wildcard characters denoting
3476     any single character and any string, respectively (these are
3477     comparable to <literal>.</> and <literal>.*</> in POSIX regular
3478     expressions).
3479    </para>
3480
3481    <para>
3482     In addition to these facilities borrowed from <function>LIKE</function>,
3483     <function>SIMILAR TO</function> supports these pattern-matching
3484     metacharacters borrowed from POSIX regular expressions:
3485
3486    <itemizedlist>
3487     <listitem>
3488      <para>
3489       <literal>|</literal> denotes alternation (either of two alternatives).
3490      </para>
3491     </listitem>
3492     <listitem>
3493      <para>
3494       <literal>*</literal> denotes repetition of the previous item zero
3495       or more times.
3496      </para>
3497     </listitem>
3498     <listitem>
3499      <para>
3500       <literal>+</literal> denotes repetition of the previous item one
3501       or more times.
3502      </para>
3503     </listitem>
3504     <listitem>
3505      <para>
3506       <literal>?</literal> denotes repetition of the previous item zero
3507       or one time.
3508      </para>
3509     </listitem>
3510     <listitem>
3511      <para>
3512       <literal>{</><replaceable>m</><literal>}</literal> denotes repetition
3513       of the previous item exactly <replaceable>m</> times.
3514      </para>
3515     </listitem>
3516     <listitem>
3517      <para>
3518       <literal>{</><replaceable>m</><literal>,}</literal> denotes repetition
3519       of the previous item <replaceable>m</> or more times.
3520      </para>
3521     </listitem>
3522     <listitem>
3523      <para>
3524       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
3525       denotes repetition of the previous item at least <replaceable>m</> and
3526       not more than <replaceable>n</> times.
3527      </para>
3528     </listitem>
3529     <listitem>
3530      <para>
3531       Parentheses <literal>()</literal> can be used to group items into
3532       a single logical item.
3533      </para>
3534     </listitem>
3535     <listitem>
3536      <para>
3537       A bracket expression <literal>[...]</literal> specifies a character
3538       class, just as in POSIX regular expressions.
3539      </para>
3540     </listitem>
3541    </itemizedlist>
3542
3543     Notice that the period (<literal>.</>) is not a metacharacter
3544     for <function>SIMILAR TO</>.
3545    </para>
3546
3547    <para>
3548     As with <function>LIKE</>, a backslash disables the special meaning
3549     of any of these metacharacters; or a different escape character can
3550     be specified with <literal>ESCAPE</>.
3551    </para>
3552
3553    <para>
3554     Some examples:
3555 <programlisting>
3556 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
3557 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
3558 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
3559 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
3560 </programlisting>
3561    </para>
3562
3563    <para>
3564     The <function>substring</> function with three parameters,
3565     <function>substring(<replaceable>string</replaceable> from
3566     <replaceable>pattern</replaceable> for
3567     <replaceable>escape-character</replaceable>)</function>, provides
3568     extraction of a substring that matches an SQL
3569     regular expression pattern.  As with <literal>SIMILAR TO</>, the
3570     specified pattern must match the entire data string, or else the
3571     function fails and returns null.  To indicate the part of the
3572     pattern that should be returned on success, the pattern must contain
3573     two occurrences of the escape character followed by a double quote
3574     (<literal>"</>). <!-- " font-lock sanity -->
3575     The text matching the portion of the pattern
3576     between these markers is returned.
3577    </para>
3578
3579    <para>
3580     Some examples, with <literal>#&quot;</> delimiting the return string:
3581 <programlisting>
3582 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
3583 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
3584 </programlisting>
3585    </para>
3586   </sect2>
3587
3588   <sect2 id="functions-posix-regexp">
3589    <title><acronym>POSIX</acronym> Regular Expressions</title>
3590
3591    <indexterm zone="functions-posix-regexp">
3592     <primary>regular expression</primary>
3593     <seealso>pattern matching</seealso>
3594    </indexterm>
3595    <indexterm>
3596     <primary>substring</primary>
3597    </indexterm>
3598    <indexterm>
3599     <primary>regexp_replace</primary>
3600    </indexterm>
3601    <indexterm>
3602     <primary>regexp_matches</primary>
3603    </indexterm>
3604    <indexterm>
3605     <primary>regexp_split_to_table</primary>
3606    </indexterm>
3607    <indexterm>
3608     <primary>regexp_split_to_array</primary>
3609    </indexterm>
3610
3611    <para>
3612     <xref linkend="functions-posix-table"> lists the available
3613     operators for pattern matching using POSIX regular expressions.
3614    </para>
3615
3616    <table id="functions-posix-table">
3617     <title>Regular Expression Match Operators</title>
3618
3619     <tgroup cols="3">
3620      <thead>
3621       <row>
3622        <entry>Operator</entry>
3623        <entry>Description</entry>
3624        <entry>Example</entry>
3625       </row>
3626      </thead>
3627
3628       <tbody>
3629        <row>
3630         <entry> <literal>~</literal> </entry>
3631         <entry>Matches regular expression, case sensitive</entry>
3632         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3633        </row>
3634
3635        <row>
3636         <entry> <literal>~*</literal> </entry>
3637         <entry>Matches regular expression, case insensitive</entry>
3638         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3639        </row>
3640
3641        <row>
3642         <entry> <literal>!~</literal> </entry>
3643         <entry>Does not match regular expression, case sensitive</entry>
3644         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3645        </row>
3646
3647        <row>
3648         <entry> <literal>!~*</literal> </entry>
3649         <entry>Does not match regular expression, case insensitive</entry>
3650         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3651        </row>
3652       </tbody>
3653      </tgroup>
3654     </table>
3655
3656     <para>
3657      <acronym>POSIX</acronym> regular expressions provide a more
3658      powerful means for pattern matching than the <function>LIKE</function> and
3659      <function>SIMILAR TO</> operators.
3660      Many Unix tools such as <command>egrep</command>,
3661      <command>sed</command>, or <command>awk</command> use a pattern
3662      matching language that is similar to the one described here.
3663     </para>
3664
3665     <para>
3666      A regular expression is a character sequence that is an
3667      abbreviated definition of a set of strings (a <firstterm>regular
3668      set</firstterm>).  A string is said to match a regular expression
3669      if it is a member of the regular set described by the regular
3670      expression.  As with <function>LIKE</function>, pattern characters
3671      match string characters exactly unless they are special characters
3672      in the regular expression language &mdash; but regular expressions use
3673      different special characters than <function>LIKE</function> does.
3674      Unlike <function>LIKE</function> patterns, a
3675      regular expression is allowed to match anywhere within a string, unless
3676      the regular expression is explicitly anchored to the beginning or
3677      end of the string.
3678     </para>
3679
3680     <para>
3681      Some examples:
3682 <programlisting>
3683 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
3684 'abc' ~ '^a'     <lineannotation>true</lineannotation>
3685 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
3686 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3687 </programlisting>
3688     </para>
3689
3690     <para>
3691      The <acronym>POSIX</acronym> pattern language is described in much
3692      greater detail below.
3693     </para>
3694
3695     <para>
3696      The <function>substring</> function with two parameters,
3697      <function>substring(<replaceable>string</replaceable> from
3698      <replaceable>pattern</replaceable>)</function>, provides extraction of a
3699      substring
3700      that matches a POSIX regular expression pattern.  It returns null if
3701      there is no match, otherwise the portion of the text that matched the
3702      pattern.  But if the pattern contains any parentheses, the portion
3703      of the text that matched the first parenthesized subexpression (the
3704      one whose left parenthesis comes first) is
3705      returned.  You can put parentheses around the whole expression
3706      if you want to use parentheses within it without triggering this
3707      exception.  If you need parentheses in the pattern before the
3708      subexpression you want to extract, see the non-capturing parentheses
3709      described below.
3710     </para>
3711
3712    <para>
3713     Some examples:
3714 <programlisting>
3715 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
3716 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
3717 </programlisting>
3718    </para>
3719
3720     <para>
3721      The <function>regexp_replace</> function provides substitution of
3722      new text for substrings that match POSIX regular expression patterns.
3723      It has the syntax
3724      <function>regexp_replace</function>(<replaceable>source</>,
3725      <replaceable>pattern</>, <replaceable>replacement</>
3726      <optional>, <replaceable>flags</> </optional>).
3727      The <replaceable>source</> string is returned unchanged if
3728      there is no match to the <replaceable>pattern</>.  If there is a
3729      match, the <replaceable>source</> string is returned with the
3730      <replaceable>replacement</> string substituted for the matching
3731      substring.  The <replaceable>replacement</> string can contain
3732      <literal>\</><replaceable>n</>, where <replaceable>n</> is 1
3733      through 9, to indicate that the source substring matching the
3734      <replaceable>n</>'th parenthesized subexpression of the pattern should be
3735      inserted, and it can contain <literal>\&amp;</> to indicate that the
3736      substring matching the entire pattern should be inserted.  Write
3737      <literal>\\</> if you need to put a literal backslash in the replacement
3738      text.
3739      The <replaceable>flags</> parameter is an optional text
3740      string containing zero or more single-letter flags that change the
3741      function's behavior.  Flag <literal>i</> specifies case-insensitive
3742      matching, while flag <literal>g</> specifies replacement of each matching
3743      substring rather than only the first one.  Other supported flags are
3744      described in <xref linkend="posix-embedded-options-table">.
3745     </para>
3746
3747    <para>
3748     Some examples:
3749 <programlisting>
3750 regexp_replace('foobarbaz', 'b..', 'X')
3751                                    <lineannotation>fooXbaz</lineannotation>
3752 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3753                                    <lineannotation>fooXX</lineannotation>
3754 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3755                                    <lineannotation>fooXarYXazY</lineannotation>
3756 </programlisting>
3757    </para>
3758
3759     <para>
3760      The <function>regexp_matches</> function returns a text array of
3761      all of the captured substrings resulting from matching a POSIX
3762      regular expression pattern.  It has the syntax
3763      <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3764      <optional>, <replaceable>flags</> </optional>).
3765      The function can return no rows, one row, or multiple rows (see
3766      the <literal>g</> flag below).  If the <replaceable>pattern</>
3767      does not match, the function returns no rows.  If the pattern
3768      contains no parenthesized subexpressions, then each row
3769      returned is a single-element text array containing the substring
3770      matching the whole pattern.  If the pattern contains parenthesized
3771      subexpressions, the function returns a text array whose
3772      <replaceable>n</>'th element is the substring matching the
3773      <replaceable>n</>'th parenthesized subexpression of the pattern
3774      (not counting <quote>non-capturing</> parentheses; see below for
3775      details).
3776      The <replaceable>flags</> parameter is an optional text
3777      string containing zero or more single-letter flags that change the
3778      function's behavior.  Flag <literal>g</> causes the function to find
3779      each match in the string, not only the first one, and return a row for
3780      each such match.  Other supported
3781      flags are described in <xref linkend="posix-embedded-options-table">.
3782     </para>
3783
3784    <para>
3785     Some examples:
3786 <programlisting>
3787 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3788  regexp_matches 
3789 ----------------
3790  {bar,beque}
3791 (1 row)
3792
3793 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3794  regexp_matches 
3795 ----------------
3796  {bar,beque}
3797  {bazil,barf}
3798 (2 rows)
3799
3800 SELECT regexp_matches('foobarbequebaz', 'barbeque');
3801  regexp_matches 
3802 ----------------
3803  {barbeque}
3804 (1 row)
3805 </programlisting>
3806    </para>
3807
3808    <para>
3809     It is possible to force <function>regexp_matches()</> to always
3810     return one row by using a sub-select;  this is particularly useful
3811     in a <literal>SELECT</> target list when you want all rows
3812     returned, even non-matching ones:
3813 <programlisting>
3814 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
3815 </programlisting>
3816    </para>
3817
3818     <para>
3819      The <function>regexp_split_to_table</> function splits a string using a POSIX
3820      regular expression pattern as a delimiter.  It has the syntax
3821      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
3822      <optional>, <replaceable>flags</> </optional>).
3823      If there is no match to the <replaceable>pattern</>, the function returns the
3824      <replaceable>string</>.  If there is at least one match, for each match it returns
3825      the text from the end of the last match (or the beginning of the string)
3826      to the beginning of the match.  When there are no more matches, it
3827      returns the text from the end of the last match to the end of the string.
3828      The <replaceable>flags</> parameter is an optional text string containing
3829      zero or more single-letter flags that change the function's behavior.
3830      <function>regexp_split_to_table</function> supports the flags described in
3831      <xref linkend="posix-embedded-options-table">.
3832     </para>
3833
3834     <para>
3835      The <function>regexp_split_to_array</> function behaves the same as
3836      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
3837      returns its result as an array of <type>text</>.  It has the syntax
3838      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
3839      <optional>, <replaceable>flags</> </optional>).
3840      The parameters are the same as for <function>regexp_split_to_table</>.
3841     </para>
3842
3843    <para>
3844     Some examples:
3845 <programlisting>
3846
3847 SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\s+') AS foo;
3848   foo   
3849 --------
3850  the    
3851  quick  
3852  brown  
3853  fox    
3854  jumped 
3855  over   
3856  the    
3857  lazy   
3858  dog    
3859 (9 rows)
3860
3861 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
3862               regexp_split_to_array             
3863 ------------------------------------------------
3864  {the,quick,brown,fox,jumped,over,the,lazy,dog}
3865 (1 row)
3866
3867 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
3868  foo 
3869 -----
3870  t         
3871  h         
3872  e         
3873  q         
3874  u         
3875  i         
3876  c         
3877  k         
3878  b         
3879  r         
3880  o         
3881  w         
3882  n         
3883  f         
3884  o         
3885  x         
3886 (16 rows)
3887 </programlisting>
3888    </para>
3889
3890    <para>
3891     As the last example demonstrates, the regexp split functions ignore
3892     zero-length matches that occur at the start or end of the string
3893     or immediately after a previous match.  This is contrary to the strict
3894     definition of regexp matching that is implemented by
3895     <function>regexp_matches</>, but is usually the most convenient behavior
3896     in practice.  Other software systems such as Perl use similar definitions.
3897    </para>
3898
3899 <!-- derived from the re_syntax.n man page -->
3900
3901    <sect3 id="posix-syntax-details">
3902     <title>Regular Expression Details</title>
3903
3904    <para>
3905     <productname>PostgreSQL</productname>'s regular expressions are implemented
3906     using a software package written by Henry Spencer.  Much of
3907     the description of regular expressions below is copied verbatim from his
3908     manual.
3909    </para>
3910
3911    <para>
3912     Regular expressions (<acronym>RE</acronym>s), as defined in
3913     <acronym>POSIX</acronym> 1003.2, come in two forms:
3914     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
3915     (roughly those of <command>egrep</command>), and
3916     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
3917     (roughly those of <command>ed</command>).
3918     <productname>PostgreSQL</productname> supports both forms, and
3919     also implements some extensions
3920     that are not in the POSIX standard, but have become widely used
3921     due to their availability in programming languages such as Perl and Tcl.
3922     <acronym>RE</acronym>s using these non-POSIX extensions are called
3923     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
3924     in this documentation.  AREs are almost an exact superset of EREs,
3925     but BREs have several notational incompatibilities (as well as being
3926     much more limited).
3927     We first describe the ARE and ERE forms, noting features that apply
3928     only to AREs, and then describe how BREs differ.
3929    </para>
3930
3931    <note>
3932     <para>
3933      <productname>PostgreSQL</> always initially presumes that a regular
3934      expression follows the ARE rules.  However, the more limited ERE or
3935      BRE rules can be chosen by prepending an <firstterm>embedded option</>
3936      to the RE pattern, as described in <xref linkend="posix-metasyntax">.
3937      This can be useful for compatibility with applications that expect
3938      exactly the <acronym>POSIX</acronym> 1003.2 rules.
3939     </para>
3940    </note>
3941
3942    <para>
3943     A regular expression is defined as one or more
3944     <firstterm>branches</firstterm>, separated by
3945     <literal>|</literal>.  It matches anything that matches one of the
3946     branches.
3947    </para>
3948
3949    <para>
3950     A branch is zero or more <firstterm>quantified atoms</> or
3951     <firstterm>constraints</>, concatenated.
3952     It matches a match for the first, followed by a match for the second, etc;
3953     an empty branch matches the empty string.
3954    </para>
3955
3956    <para>
3957     A quantified atom is an <firstterm>atom</> possibly followed
3958     by a single <firstterm>quantifier</>.
3959     Without a quantifier, it matches a match for the atom.
3960     With a quantifier, it can match some number of matches of the atom.
3961     An <firstterm>atom</firstterm> can be any of the possibilities
3962     shown in <xref linkend="posix-atoms-table">.
3963     The possible quantifiers and their meanings are shown in
3964     <xref linkend="posix-quantifiers-table">.
3965    </para>
3966
3967    <para>
3968     A <firstterm>constraint</> matches an empty string, but matches only when
3969     specific conditions are met.  A constraint can be used where an atom
3970     could be used, except it cannot be followed by a quantifier.
3971     The simple constraints are shown in
3972     <xref linkend="posix-constraints-table">;
3973     some more constraints are described later.
3974    </para>
3975
3976
3977    <table id="posix-atoms-table">
3978     <title>Regular Expression Atoms</title>
3979
3980     <tgroup cols="2">
3981      <thead>
3982       <row>
3983        <entry>Atom</entry>
3984        <entry>Description</entry>
3985       </row>
3986      </thead>
3987
3988       <tbody>
3989        <row>
3990        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3991        <entry> (where <replaceable>re</> is any regular expression)
3992        matches a match for
3993        <replaceable>re</>, with the match noted for possible reporting </entry>
3994        </row>
3995
3996        <row>
3997        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3998        <entry> as above, but the match is not noted for reporting
3999        (a <quote>non-capturing</> set of parentheses)
4000        (AREs only) </entry>
4001        </row>
4002
4003        <row>
4004        <entry> <literal>.</> </entry>
4005        <entry> matches any single character </entry>
4006        </row>
4007
4008        <row>
4009        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
4010        <entry> a <firstterm>bracket expression</>,
4011        matching any one of the <replaceable>chars</> (see
4012        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
4013        </row>
4014
4015        <row>
4016        <entry> <literal>\</><replaceable>k</> </entry>
4017        <entry> (where <replaceable>k</> is a non-alphanumeric character)
4018        matches that character taken as an ordinary character,
4019        e.g., <literal>\\</> matches a backslash character </entry>
4020        </row>
4021
4022        <row>
4023        <entry> <literal>\</><replaceable>c</> </entry>
4024        <entry> where <replaceable>c</> is alphanumeric
4025        (possibly followed by other characters)
4026        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
4027        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
4028        </row>
4029
4030        <row>
4031        <entry> <literal>{</> </entry>
4032        <entry> when followed by a character other than a digit,
4033        matches the left-brace character <literal>{</>;
4034        when followed by a digit, it is the beginning of a
4035        <replaceable>bound</> (see below) </entry>
4036        </row>
4037
4038        <row>
4039        <entry> <replaceable>x</> </entry>
4040        <entry> where <replaceable>x</> is a single character with no other
4041        significance, matches that character </entry>
4042        </row>
4043       </tbody>
4044      </tgroup>
4045     </table>
4046
4047    <para>
4048     An RE cannot end with a backslash (<literal>\</>).
4049    </para>
4050
4051    <note>
4052     <para>
4053      If you have <xref linkend="guc-standard-conforming-strings"> turned off,
4054      any backslashes you write in literal string constants will need to be
4055      doubled.  See <xref linkend="sql-syntax-strings"> for more information.
4056     </para>
4057    </note>
4058
4059    <table id="posix-quantifiers-table">
4060     <title>Regular Expression Quantifiers</title>
4061
4062     <tgroup cols="2">
4063      <thead>
4064       <row>
4065        <entry>Quantifier</entry>
4066        <entry>Matches</entry>
4067       </row>
4068      </thead>
4069
4070       <tbody>
4071        <row>
4072        <entry> <literal>*</> </entry>
4073        <entry> a sequence of 0 or more matches of the atom </entry>
4074        </row>
4075
4076        <row>
4077        <entry> <literal>+</> </entry>
4078        <entry> a sequence of 1 or more matches of the atom </entry>
4079        </row>
4080
4081        <row>
4082        <entry> <literal>?</> </entry>
4083        <entry> a sequence of 0 or 1 matches of the atom </entry>
4084        </row>
4085
4086        <row>
4087        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
4088        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
4089        </row>
4090
4091        <row>
4092        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
4093        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
4094        </row>
4095
4096        <row>
4097        <entry>
4098        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4099        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
4100        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
4101        <replaceable>n</> </entry>
4102        </row>
4103
4104        <row>
4105        <entry> <literal>*?</> </entry>
4106        <entry> non-greedy version of <literal>*</> </entry>
4107        </row>
4108
4109        <row>
4110        <entry> <literal>+?</> </entry>
4111        <entry> non-greedy version of <literal>+</> </entry>
4112        </row>
4113
4114        <row>
4115        <entry> <literal>??</> </entry>
4116        <entry> non-greedy version of <literal>?</> </entry>
4117        </row>
4118
4119        <row>
4120        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
4121        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
4122        </row>
4123
4124        <row>
4125        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
4126        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
4127        </row>
4128
4129        <row>
4130        <entry>
4131        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
4132        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4133        </row>
4134       </tbody>
4135      </tgroup>
4136     </table>
4137
4138    <para>
4139     The forms using <literal>{</><replaceable>...</><literal>}</>
4140     are known as <firstterm>bounds</>.
4141     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
4142     unsigned decimal integers with permissible values from 0 to 255 inclusive.
4143    </para>
4144
4145     <para>
4146      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
4147      same possibilities as their corresponding normal (<firstterm>greedy</>)
4148      counterparts, but prefer the smallest number rather than the largest
4149      number of matches.
4150      See <xref linkend="posix-matching-rules"> for more detail.
4151    </para>
4152
4153    <note>
4154     <para>
4155      A quantifier cannot immediately follow another quantifier, e.g.,
4156      <literal>**</> is invalid.
4157      A quantifier cannot
4158      begin an expression or subexpression or follow
4159      <literal>^</literal> or <literal>|</literal>.
4160     </para>
4161    </note>
4162
4163    <table id="posix-constraints-table">
4164     <title>Regular Expression Constraints</title>
4165
4166     <tgroup cols="2">
4167      <thead>
4168       <row>
4169        <entry>Constraint</entry>
4170        <entry>Description</entry>
4171       </row>
4172      </thead>
4173
4174       <tbody>
4175        <row>
4176        <entry> <literal>^</> </entry>
4177        <entry> matches at the beginning of the string </entry>
4178        </row>
4179
4180        <row>
4181        <entry> <literal>$</> </entry>
4182        <entry> matches at the end of the string </entry>
4183        </row>
4184
4185        <row>
4186        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
4187        <entry> <firstterm>positive lookahead</> matches at any point
4188        where a substring matching <replaceable>re</> begins
4189        (AREs only) </entry>
4190        </row>
4191
4192        <row>
4193        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
4194        <entry> <firstterm>negative lookahead</> matches at any point
4195        where no substring matching <replaceable>re</> begins
4196        (AREs only) </entry>
4197        </row>
4198       </tbody>
4199      </tgroup>
4200     </table>
4201
4202    <para>
4203     Lookahead constraints cannot contain <firstterm>back references</>
4204     (see <xref linkend="posix-escape-sequences">),
4205     and all parentheses within them are considered non-capturing.
4206    </para>
4207    </sect3>
4208
4209    <sect3 id="posix-bracket-expressions">
4210     <title>Bracket Expressions</title>
4211
4212    <para>
4213     A <firstterm>bracket expression</firstterm> is a list of
4214     characters enclosed in <literal>[]</literal>.  It normally matches
4215     any single character from the list (but see below).  If the list
4216     begins with <literal>^</literal>, it matches any single character
4217     <emphasis>not</> from the rest of the list.
4218     If two characters
4219     in the list are separated by <literal>-</literal>, this is
4220     shorthand for the full range of characters between those two
4221     (inclusive) in the collating sequence,
4222     e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
4223     any decimal digit.  It is illegal for two ranges to share an
4224     endpoint, e.g.,  <literal>a-c-e</literal>.  Ranges are very
4225     collating-sequence-dependent, so portable programs should avoid
4226     relying on them.
4227    </para>
4228
4229    <para>
4230     To include a literal <literal>]</literal> in the list, make it the
4231     first character (after <literal>^</literal>, if that is used).  To
4232     include a literal <literal>-</literal>, make it the first or last
4233     character, or the second endpoint of a range.  To use a literal
4234     <literal>-</literal> as the first endpoint of a range, enclose it
4235     in <literal>[.</literal> and <literal>.]</literal> to make it a
4236     collating element (see below).  With the exception of these characters,
4237     some combinations using <literal>[</literal>
4238     (see next paragraphs), and escapes (AREs only), all other special
4239     characters lose their special significance within a bracket expression.
4240     In particular, <literal>\</literal> is not special when following
4241     ERE or BRE rules, though it is special (as introducing an escape)
4242     in AREs.
4243    </para>
4244
4245    <para>
4246     Within a bracket expression, a collating element (a character, a
4247     multiple-character sequence that collates as if it were a single
4248     character, or a collating-sequence name for either) enclosed in
4249     <literal>[.</literal> and <literal>.]</literal> stands for the
4250     sequence of characters of that collating element.  The sequence is
4251     treated as a single element of the bracket expression's list.  This
4252     allows a bracket
4253     expression containing a multiple-character collating element to
4254     match more than one character, e.g., if the collating sequence
4255     includes a <literal>ch</literal> collating element, then the RE
4256     <literal>[[.ch.]]*c</literal> matches the first five characters of
4257     <literal>chchcc</literal>.
4258    </para>
4259
4260    <note>
4261     <para>
4262      <productname>PostgreSQL</> currently does not support multi-character collating
4263      elements. This information describes possible future behavior.
4264     </para>
4265    </note>
4266
4267    <para>
4268     Within a bracket expression, a collating element enclosed in
4269     <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
4270     class</>, standing for the sequences of characters of all collating
4271     elements equivalent to that one, including itself.  (If there are
4272     no other equivalent collating elements, the treatment is as if the
4273     enclosing delimiters were <literal>[.</literal> and
4274     <literal>.]</literal>.)  For example, if <literal>o</literal> and
4275     <literal>^</literal> are the members of an equivalence class, then
4276     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
4277     <literal>[o^]</literal> are all synonymous.  An equivalence class
4278     cannot be an endpoint of a range.
4279    </para>
4280
4281    <para>
4282     Within a bracket expression, the name of a character class
4283     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
4284     for the list of all characters belonging to that class.  Standard
4285     character class names are: <literal>alnum</literal>,
4286     <literal>alpha</literal>, <literal>blank</literal>,
4287     <literal>cntrl</literal>, <literal>digit</literal>,
4288     <literal>graph</literal>, <literal>lower</literal>,
4289     <literal>print</literal>, <literal>punct</literal>,
4290     <literal>space</literal>, <literal>upper</literal>,
4291     <literal>xdigit</literal>.  These stand for the character classes
4292     defined in
4293     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
4294     A locale can provide others.  A character class cannot be used as
4295     an endpoint of a range.
4296    </para>
4297
4298    <para>
4299     There are two special cases of bracket expressions:  the bracket
4300     expressions <literal>[[:&lt;:]]</literal> and
4301     <literal>[[:&gt;:]]</literal> are constraints,
4302     matching empty strings at the beginning
4303     and end of a word respectively.  A word is defined as a sequence
4304     of word characters that is neither preceded nor followed by word
4305     characters.  A word character is an <literal>alnum</> character (as
4306     defined by
4307     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
4308     or an underscore.  This is an extension, compatible with but not
4309     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
4310     caution in software intended to be portable to other systems.
4311     The constraint escapes described below are usually preferable; they
4312     are no more standard, but are easier to type.
4313    </para>
4314    </sect3>
4315
4316    <sect3 id="posix-escape-sequences">
4317     <title>Regular Expression Escapes</title>
4318
4319    <para>
4320     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
4321     followed by an alphanumeric character. Escapes come in several varieties:
4322     character entry, class shorthands, constraint escapes, and back references.
4323     A <literal>\</> followed by an alphanumeric character but not constituting
4324     a valid escape is illegal in AREs.
4325     In EREs, there are no escapes: outside a bracket expression,
4326     a <literal>\</> followed by an alphanumeric character merely stands for
4327     that character as an ordinary character, and inside a bracket expression,
4328     <literal>\</> is an ordinary character.
4329     (The latter is the one actual incompatibility between EREs and AREs.)
4330    </para>
4331
4332    <para>
4333     <firstterm>Character-entry escapes</> exist to make it easier to specify
4334     non-printing and other inconvenient characters in REs.  They are
4335     shown in <xref linkend="posix-character-entry-escapes-table">.
4336    </para>
4337
4338    <para>
4339     <firstterm>Class-shorthand escapes</> provide shorthands for certain
4340     commonly-used character classes.  They are
4341     shown in <xref linkend="posix-class-shorthand-escapes-table">.
4342    </para>
4343
4344    <para>
4345     A <firstterm>constraint escape</> is a constraint,
4346     matching the empty string if specific conditions are met,
4347     written as an escape.  They are
4348     shown in <xref linkend="posix-constraint-escapes-table">.
4349    </para>
4350
4351    <para>
4352     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
4353     same string matched by the previous parenthesized subexpression specified
4354     by the number <replaceable>n</>
4355     (see <xref linkend="posix-constraint-backref-table">).  For example,
4356     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
4357     but not <literal>bc</> or <literal>cb</>.
4358     The subexpression must entirely precede the back reference in the RE.
4359     Subexpressions are numbered in the order of their leading parentheses.
4360     Non-capturing parentheses do not define subexpressions.
4361    </para>
4362
4363    <note>
4364     <para>
4365      Keep in mind that an escape's leading <literal>\</> will need to be
4366      doubled when entering the pattern as an SQL string constant.  For example:
4367 <programlisting>
4368 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
4369 </programlisting>
4370     </para>
4371    </note>
4372
4373    <table id="posix-character-entry-escapes-table">
4374     <title>Regular Expression Character-entry Escapes</title>
4375
4376     <tgroup cols="2">
4377      <thead>
4378       <row>
4379        <entry>Escape</entry>
4380        <entry>Description</entry>
4381       </row>
4382      </thead>
4383
4384       <tbody>
4385        <row>
4386        <entry> <literal>\a</> </entry>
4387        <entry> alert (bell) character, as in C </entry>
4388        </row>
4389
4390        <row>
4391        <entry> <literal>\b</> </entry>
4392        <entry> backspace, as in C </entry>
4393        </row>
4394
4395        <row>
4396        <entry> <literal>\B</> </entry>
4397        <entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
4398        doubling </entry>
4399        </row>
4400
4401        <row>
4402        <entry> <literal>\c</><replaceable>X</> </entry>
4403        <entry> (where <replaceable>X</> is any character) the character whose
4404        low-order 5 bits are the same as those of
4405        <replaceable>X</>, and whose other bits are all zero </entry>
4406        </row>
4407
4408        <row>
4409        <entry> <literal>\e</> </entry>
4410        <entry> the character whose collating-sequence name
4411        is <literal>ESC</>,
4412        or failing that, the character with octal value 033 </entry>
4413        </row>
4414
4415        <row>
4416        <entry> <literal>\f</> </entry>
4417        <entry> form feed, as in C </entry>
4418        </row>
4419
4420        <row>
4421        <entry> <literal>\n</> </entry>
4422        <entry> newline, as in C </entry>
4423        </row>
4424
4425        <row>
4426        <entry> <literal>\r</> </entry>
4427        <entry> carriage return, as in C </entry>
4428        </row>
4429
4430        <row>
4431        <entry> <literal>\t</> </entry>
4432        <entry> horizontal tab, as in C </entry>
4433        </row>
4434
4435        <row>
4436        <entry> <literal>\u</><replaceable>wxyz</> </entry>
4437        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4438        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4439        in the local byte ordering </entry>
4440        </row>
4441
4442        <row>
4443        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4444        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4445        digits)
4446        reserved for a hypothetical Unicode extension to 32 bits
4447        </entry>
4448        </row>
4449
4450        <row>
4451        <entry> <literal>\v</> </entry>
4452        <entry> vertical tab, as in C </entry>
4453        </row>
4454
4455        <row>
4456        <entry> <literal>\x</><replaceable>hhh</> </entry>
4457        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4458        digits)
4459        the character whose hexadecimal value is
4460        <literal>0x</><replaceable>hhh</>
4461        (a single character no matter how many hexadecimal digits are used)
4462        </entry>
4463        </row>
4464
4465        <row>
4466        <entry> <literal>\0</> </entry>
4467        <entry> the character whose value is <literal>0</> (the null byte)</entry>
4468        </row>
4469
4470        <row>
4471        <entry> <literal>\</><replaceable>xy</> </entry>
4472        <entry> (where <replaceable>xy</> is exactly two octal digits,
4473        and is not a <firstterm>back reference</>)
4474        the character whose octal value is
4475        <literal>0</><replaceable>xy</> </entry>
4476        </row>
4477
4478        <row>
4479        <entry> <literal>\</><replaceable>xyz</> </entry>
4480        <entry> (where <replaceable>xyz</> is exactly three octal digits,
4481        and is not a <firstterm>back reference</>)
4482        the character whose octal value is
4483        <literal>0</><replaceable>xyz</> </entry>
4484        </row>
4485       </tbody>
4486      </tgroup>
4487     </table>
4488
4489    <para>
4490     Hexadecimal digits are <literal>0</>-<literal>9</>,
4491     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4492     Octal digits are <literal>0</>-<literal>7</>.
4493    </para>
4494
4495    <para>
4496     The character-entry escapes are always taken as ordinary characters.
4497     For example, <literal>\135</> is <literal>]</> in ASCII, but
4498     <literal>\135</> does not terminate a bracket expression.
4499    </para>
4500
4501    <table id="posix-class-shorthand-escapes-table">
4502     <title>Regular Expression Class-shorthand Escapes</title>
4503
4504     <tgroup cols="2">
4505      <thead>
4506       <row>
4507        <entry>Escape</entry>
4508        <entry>Description</entry>
4509       </row>
4510      </thead>
4511
4512       <tbody>
4513        <row>
4514        <entry> <literal>\d</> </entry>
4515        <entry> <literal>[[:digit:]]</> </entry>
4516        </row>
4517
4518        <row>
4519        <entry> <literal>\s</> </entry>
4520        <entry> <literal>[[:space:]]</> </entry>
4521        </row>
4522
4523        <row>
4524        <entry> <literal>\w</> </entry>
4525        <entry> <literal>[[:alnum:]_]</>
4526        (note underscore is included) </entry>
4527        </row>
4528
4529        <row>
4530        <entry> <literal>\D</> </entry>
4531        <entry> <literal>[^[:digit:]]</> </entry>
4532        </row>
4533
4534        <row>
4535        <entry> <literal>\S</> </entry>
4536        <entry> <literal>[^[:space:]]</> </entry>
4537        </row>
4538
4539        <row>
4540        <entry> <literal>\W</> </entry>
4541        <entry> <literal>[^[:alnum:]_]</>
4542        (note underscore is included) </entry>
4543        </row>
4544       </tbody>
4545      </tgroup>
4546     </table>
4547
4548    <para>
4549     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4550     and <literal>\w</> lose their outer brackets,
4551     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4552     (So, for example, <literal>[a-c\d]</> is equivalent to
4553     <literal>[a-c[:digit:]]</>.
4554     Also, <literal>[a-c\D]</>, which is equivalent to
4555     <literal>[a-c^[:digit:]]</>, is illegal.)
4556    </para>
4557
4558    <table id="posix-constraint-escapes-table">
4559     <title>Regular Expression Constraint Escapes</title>
4560
4561     <tgroup cols="2">
4562      <thead>
4563       <row>
4564        <entry>Escape</entry>
4565        <entry>Description</entry>
4566       </row>
4567      </thead>
4568
4569       <tbody>
4570        <row>
4571        <entry> <literal>\A</> </entry>
4572        <entry> matches only at the beginning of the string
4573        (see <xref linkend="posix-matching-rules"> for how this differs from
4574        <literal>^</>) </entry>
4575        </row>
4576
4577        <row>
4578        <entry> <literal>\m</> </entry>
4579        <entry> matches only at the beginning of a word </entry>
4580        </row>
4581
4582        <row>
4583        <entry> <literal>\M</> </entry>
4584        <entry> matches only at the end of a word </entry>
4585        </row>
4586
4587        <row>
4588        <entry> <literal>\y</> </entry>
4589        <entry> matches only at the beginning or end of a word </entry>
4590        </row>
4591
4592        <row>
4593        <entry> <literal>\Y</> </entry>
4594        <entry> matches only at a point that is not the beginning or end of a
4595        word </entry>
4596        </row>
4597
4598        <row>
4599        <entry> <literal>\Z</> </entry>
4600        <entry> matches only at the end of the string
4601        (see <xref linkend="posix-matching-rules"> for how this differs from
4602        <literal>$</>) </entry>
4603        </row>
4604       </tbody>
4605      </tgroup>
4606     </table>
4607
4608    <para>
4609     A word is defined as in the specification of
4610     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4611     Constraint escapes are illegal within bracket expressions.
4612    </para>
4613
4614    <table id="posix-constraint-backref-table">
4615     <title>Regular Expression Back References</title>
4616
4617     <tgroup cols="2">
4618      <thead>
4619       <row>
4620        <entry>Escape</entry>
4621        <entry>Description</entry>
4622       </row>
4623      </thead>
4624
4625       <tbody>
4626        <row>
4627        <entry> <literal>\</><replaceable>m</> </entry>
4628        <entry> (where <replaceable>m</> is a nonzero digit)
4629        a back reference to the <replaceable>m</>'th subexpression </entry>
4630        </row>
4631
4632        <row>
4633        <entry> <literal>\</><replaceable>mnn</> </entry>
4634        <entry> (where <replaceable>m</> is a nonzero digit, and
4635        <replaceable>nn</> is some more digits, and the decimal value
4636        <replaceable>mnn</> is not greater than the number of closing capturing
4637        parentheses seen so far)
4638        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4639        </row>
4640       </tbody>
4641      </tgroup>
4642     </table>
4643
4644    <note>
4645     <para>
4646      There is an inherent ambiguity between octal character-entry
4647      escapes and back references, which is resolved by the following heuristics,
4648      as hinted at above.
4649      A leading zero always indicates an octal escape.
4650      A single non-zero digit, not followed by another digit,
4651      is always taken as a back reference.
4652      A multi-digit sequence not starting with a zero is taken as a back
4653      reference if it comes after a suitable subexpression
4654      (i.e., the number is in the legal range for a back reference),
4655      and otherwise is taken as octal.
4656     </para>
4657    </note>
4658    </sect3>
4659
4660    <sect3 id="posix-metasyntax">
4661     <title>Regular Expression Metasyntax</title>
4662
4663    <para>
4664     In addition to the main syntax described above, there are some special
4665     forms and miscellaneous syntactic facilities available.
4666    </para>
4667
4668    <para>
4669     An RE can begin with one of two special <firstterm>director</> prefixes.
4670     If an RE begins with <literal>***:</>,
4671     the rest of the RE is taken as an ARE.  (This normally has no effect in
4672     <productname>PostgreSQL</>, since REs are assumed to be AREs;
4673     but it does have an effect if ERE or BRE mode had been specified by
4674     the <replaceable>flags</> parameter to a regex function.)
4675     If an RE begins with <literal>***=</>,
4676     the rest of the RE is taken to be a literal string,
4677     with all characters considered ordinary characters.
4678    </para>
4679
4680    <para>
4681     An ARE can begin with <firstterm>embedded options</>:
4682     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4683     (where <replaceable>xyz</> is one or more alphabetic characters)
4684     specifies options affecting the rest of the RE.
4685     These options override any previously determined options &mdash;
4686     in particular, they can override the case-sensitivity behavior implied by
4687     a regex operator, or the <replaceable>flags</> parameter to a regex
4688     function.
4689     The available option letters are
4690     shown in <xref linkend="posix-embedded-options-table">.
4691     Note that these same option letters are used in the <replaceable>flags</>
4692     parameters of regex functions.
4693    </para>
4694
4695    <table id="posix-embedded-options-table">
4696     <title>ARE Embedded-option Letters</title>
4697
4698     <tgroup cols="2">
4699      <thead>
4700       <row>
4701        <entry>Option</entry>
4702        <entry>Description</entry>
4703       </row>
4704      </thead>
4705
4706       <tbody>
4707        <row>
4708        <entry> <literal>b</> </entry>
4709        <entry> rest of RE is a BRE </entry>
4710        </row>
4711
4712        <row>
4713        <entry> <literal>c</> </entry>
4714        <entry> case-sensitive matching (overrides operator type) </entry>
4715        </row>
4716
4717        <row>
4718        <entry> <literal>e</> </entry>
4719        <entry> rest of RE is an ERE </entry>
4720        </row>
4721
4722        <row>
4723        <entry> <literal>i</> </entry>
4724        <entry> case-insensitive matching (see
4725        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4726        </row>
4727
4728        <row>
4729        <entry> <literal>m</> </entry>
4730        <entry> historical synonym for <literal>n</> </entry>
4731        </row>
4732
4733        <row>
4734        <entry> <literal>n</> </entry>
4735        <entry> newline-sensitive matching (see
4736        <xref linkend="posix-matching-rules">) </entry>
4737        </row>
4738
4739        <row>
4740        <entry> <literal>p</> </entry>
4741        <entry> partial newline-sensitive matching (see
4742        <xref linkend="posix-matching-rules">) </entry>
4743        </row>
4744
4745        <row>
4746        <entry> <literal>q</> </entry>
4747        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4748        characters </entry>
4749        </row>
4750
4751        <row>
4752        <entry> <literal>s</> </entry>
4753        <entry> non-newline-sensitive matching (default) </entry>
4754        </row>
4755
4756        <row>
4757        <entry> <literal>t</> </entry>
4758        <entry> tight syntax (default; see below) </entry>
4759        </row>
4760
4761        <row>
4762        <entry> <literal>w</> </entry>
4763        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4764        (see <xref linkend="posix-matching-rules">) </entry>
4765        </row>
4766
4767        <row>
4768        <entry> <literal>x</> </entry>
4769        <entry> expanded syntax (see below) </entry>
4770        </row>
4771       </tbody>
4772      </tgroup>
4773     </table>
4774
4775    <para>
4776     Embedded options take effect at the <literal>)</> terminating the sequence.
4777     They can appear only at the start of an ARE (after the
4778     <literal>***:</> director if any).
4779    </para>
4780
4781    <para>
4782     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4783     characters are significant, there is an <firstterm>expanded</> syntax,
4784     available by specifying the embedded <literal>x</> option.
4785     In the expanded syntax,
4786     white-space characters in the RE are ignored, as are
4787     all characters between a <literal>#</>
4788     and the following newline (or the end of the RE).  This
4789     permits paragraphing and commenting a complex RE.
4790     There are three exceptions to that basic rule:
4791
4792     <itemizedlist>
4793      <listitem>
4794       <para>
4795        a white-space character or <literal>#</> preceded by <literal>\</> is
4796        retained
4797       </para>
4798      </listitem>
4799      <listitem>
4800       <para>
4801        white space or <literal>#</> within a bracket expression is retained
4802       </para>
4803      </listitem>
4804      <listitem>
4805       <para>
4806        white space and comments cannot appear within multi-character symbols,
4807        such as <literal>(?:</>
4808       </para>
4809      </listitem>
4810     </itemizedlist>
4811
4812     For this purpose, white-space characters are blank, tab, newline, and
4813     any character that belongs to the <replaceable>space</> character class.
4814    </para>
4815
4816    <para>
4817     Finally, in an ARE, outside bracket expressions, the sequence
4818     <literal>(?#</><replaceable>ttt</><literal>)</>
4819     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4820     is a comment, completely ignored.
4821     Again, this is not allowed between the characters of
4822     multi-character symbols, like <literal>(?:</>.
4823     Such comments are more a historical artifact than a useful facility,
4824     and their use is deprecated; use the expanded syntax instead.
4825    </para>
4826
4827    <para>
4828     <emphasis>None</> of these metasyntax extensions is available if
4829     an initial <literal>***=</> director
4830     has specified that the user's input be treated as a literal string
4831     rather than as an RE.
4832    </para>
4833    </sect3>
4834
4835    <sect3 id="posix-matching-rules">
4836     <title>Regular Expression Matching Rules</title>
4837
4838    <para>
4839     In the event that an RE could match more than one substring of a given
4840     string, the RE matches the one starting earliest in the string.
4841     If the RE could match more than one substring starting at that point,
4842     either the longest possible match or the shortest possible match will
4843     be taken, depending on whether the RE is <firstterm>greedy</> or
4844     <firstterm>non-greedy</>.
4845    </para>
4846
4847    <para>
4848     Whether an RE is greedy or not is determined by the following rules:
4849     <itemizedlist>
4850      <listitem>
4851       <para>
4852        Most atoms, and all constraints, have no greediness attribute (because
4853        they cannot match variable amounts of text anyway).
4854       </para>
4855      </listitem>
4856      <listitem>
4857       <para>
4858        Adding parentheses around an RE does not change its greediness.
4859       </para>
4860      </listitem>
4861      <listitem>
4862       <para>
4863        A quantified atom with a fixed-repetition quantifier
4864        (<literal>{</><replaceable>m</><literal>}</>
4865        or
4866        <literal>{</><replaceable>m</><literal>}?</>)
4867        has the same greediness (possibly none) as the atom itself.
4868       </para>
4869      </listitem>
4870      <listitem>
4871       <para>
4872        A quantified atom with other normal quantifiers (including
4873        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4874        with <replaceable>m</> equal to <replaceable>n</>)
4875        is greedy (prefers longest match).
4876       </para>
4877      </listitem>
4878      <listitem>
4879       <para>
4880        A quantified atom with a non-greedy quantifier (including
4881        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4882        with <replaceable>m</> equal to <replaceable>n</>)
4883        is non-greedy (prefers shortest match).
4884       </para>
4885      </listitem>
4886      <listitem>
4887       <para>
4888        A branch &mdash; that is, an RE that has no top-level
4889        <literal>|</> operator &mdash; has the same greediness as the first
4890        quantified atom in it that has a greediness attribute.
4891       </para>
4892      </listitem>
4893      <listitem>
4894       <para>
4895        An RE consisting of two or more branches connected by the
4896        <literal>|</> operator is always greedy.
4897       </para>
4898      </listitem>
4899     </itemizedlist>
4900    </para>
4901
4902    <para>
4903     The above rules associate greediness attributes not only with individual
4904     quantified atoms, but with branches and entire REs that contain quantified
4905     atoms.  What that means is that the matching is done in such a way that
4906     the branch, or whole RE, matches the longest or shortest possible
4907     substring <emphasis>as a whole</>.  Once the length of the entire match
4908     is determined, the part of it that matches any particular subexpression
4909     is determined on the basis of the greediness attribute of that
4910     subexpression, with subexpressions starting earlier in the RE taking
4911     priority over ones starting later.
4912    </para>
4913
4914    <para>
4915     An example of what this means:
4916 <screen>
4917 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4918 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4919 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4920 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4921 </screen>
4922     In the first case, the RE as a whole is greedy because <literal>Y*</>
4923     is greedy.  It can match beginning at the <literal>Y</>, and it matches
4924     the longest possible string starting there, i.e., <literal>Y123</>.
4925     The output is the parenthesized part of that, or <literal>123</>.
4926     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4927     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
4928     the shortest possible string starting there, i.e., <literal>Y1</>.
4929     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4930     the decision as to the overall match length; so it is forced to match
4931     just <literal>1</>.
4932    </para>
4933
4934    <para>
4935     In short, when an RE contains both greedy and non-greedy subexpressions,
4936     the total match length is either as long as possible or as short as
4937     possible, according to the attribute assigned to the whole RE.  The
4938     attributes assigned to the subexpressions only affect how much of that
4939     match they are allowed to <quote>eat</> relative to each other.
4940    </para>
4941
4942    <para>
4943     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4944     can be used to force greediness or non-greediness, respectively,
4945     on a subexpression or a whole RE.
4946    </para>
4947
4948    <para>
4949     Match lengths are measured in characters, not collating elements.
4950     An empty string is considered longer than no match at all.
4951     For example:
4952     <literal>bb*</>
4953     matches the three middle characters of <literal>abbbc</>;
4954     <literal>(week|wee)(night|knights)</>
4955     matches all ten characters of <literal>weeknights</>;
4956     when <literal>(.*).*</>
4957     is matched against <literal>abc</> the parenthesized subexpression
4958     matches all three characters; and when
4959     <literal>(a*)*</> is matched against <literal>bc</>
4960     both the whole RE and the parenthesized
4961     subexpression match an empty string.
4962    </para>
4963
4964    <para>
4965     If case-independent matching is specified,
4966     the effect is much as if all case distinctions had vanished from the
4967     alphabet.
4968     When an alphabetic that exists in multiple cases appears as an
4969     ordinary character outside a bracket expression, it is effectively
4970     transformed into a bracket expression containing both cases,
4971     e.g., <literal>x</> becomes <literal>[xX]</>.
4972     When it appears inside a bracket expression, all case counterparts
4973     of it are added to the bracket expression, e.g.,
4974     <literal>[x]</> becomes <literal>[xX]</>
4975     and <literal>[^x]</> becomes <literal>[^xX]</>.
4976    </para>
4977
4978    <para>
4979     If newline-sensitive matching is specified, <literal>.</>
4980     and bracket expressions using <literal>^</>
4981     will never match the newline character
4982     (so that matches will never cross newlines unless the RE
4983     explicitly arranges it)
4984     and <literal>^</> and <literal>$</>
4985     will match the empty string after and before a newline
4986     respectively, in addition to matching at beginning and end of string
4987     respectively.
4988     But the ARE escapes <literal>\A</> and <literal>\Z</>
4989     continue to match beginning or end of string <emphasis>only</>.
4990    </para>
4991
4992    <para>
4993     If partial newline-sensitive matching is specified,
4994     this affects <literal>.</> and bracket expressions
4995     as with newline-sensitive matching, but not <literal>^</>
4996     and <literal>$</>.
4997    </para>
4998
4999    <para>
5000     If inverse partial newline-sensitive matching is specified,
5001     this affects <literal>^</> and <literal>$</>
5002     as with newline-sensitive matching, but not <literal>.</>
5003     and bracket expressions.
5004     This isn't very useful but is provided for symmetry.
5005    </para>
5006    </sect3>
5007
5008    <sect3 id="posix-limits-compatibility">
5009     <title>Limits and Compatibility</title>
5010
5011    <para>
5012     No particular limit is imposed on the length of REs in this
5013     implementation.  However,
5014     programs intended to be highly portable should not employ REs longer
5015     than 256 bytes,
5016     as a POSIX-compliant implementation can refuse to accept such REs.
5017    </para>
5018
5019    <para>
5020     The only feature of AREs that is actually incompatible with
5021     POSIX EREs is that <literal>\</> does not lose its special
5022     significance inside bracket expressions.
5023     All other ARE features use syntax which is illegal or has
5024     undefined or unspecified effects in POSIX EREs;
5025     the <literal>***</> syntax of directors likewise is outside the POSIX
5026     syntax for both BREs and EREs.
5027    </para>
5028
5029    <para>
5030     Many of the ARE extensions are borrowed from Perl, but some have
5031     been changed to clean them up, and a few Perl extensions are not present.
5032     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
5033     the lack of special treatment for a trailing newline,
5034     the addition of complemented bracket expressions to the things
5035     affected by newline-sensitive matching,
5036     the restrictions on parentheses and back references in lookahead
5037     constraints, and the longest/shortest-match (rather than first-match)
5038     matching semantics.
5039    </para>
5040
5041    <para>
5042     Two significant incompatibilities exist between AREs and the ERE syntax
5043     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
5044
5045     <itemizedlist>
5046      <listitem>
5047       <para>
5048        In AREs, <literal>\</> followed by an alphanumeric character is either
5049        an escape or an error, while in previous releases, it was just another
5050        way of writing the alphanumeric.
5051        This should not be much of a problem because there was no reason to
5052        write such a sequence in earlier releases.
5053       </para>
5054      </listitem>
5055      <listitem>
5056       <para>
5057        In AREs, <literal>\</> remains a special character within
5058        <literal>[]</>, so a literal <literal>\</> within a bracket
5059        expression must be written <literal>\\</>.
5060       </para>
5061      </listitem>
5062     </itemizedlist>
5063    </para>
5064    </sect3>
5065
5066    <sect3 id="posix-basic-regexes">
5067     <title>Basic Regular Expressions</title>
5068
5069    <para>
5070     BREs differ from EREs in several respects.
5071     In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
5072     are ordinary characters and there is no equivalent
5073     for their functionality.
5074     The delimiters for bounds are
5075     <literal>\{</> and <literal>\}</>,
5076     with <literal>{</> and <literal>}</>
5077     by themselves ordinary characters.
5078     The parentheses for nested subexpressions are
5079     <literal>\(</> and <literal>\)</>,
5080     with <literal>(</> and <literal>)</> by themselves ordinary characters.
5081     <literal>^</> is an ordinary character except at the beginning of the
5082     RE or the beginning of a parenthesized subexpression,
5083     <literal>$</> is an ordinary character except at the end of the
5084     RE or the end of a parenthesized subexpression,
5085     and <literal>*</> is an ordinary character if it appears at the beginning
5086     of the RE or the beginning of a parenthesized subexpression
5087     (after a possible leading <literal>^</>).
5088     Finally, single-digit back references are available, and
5089     <literal>\&lt;</> and <literal>\&gt;</>
5090     are synonyms for
5091     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
5092     respectively; no other escapes are available in BREs.
5093    </para>
5094    </sect3>
5095
5096 <!-- end re_syntax.n man page -->
5097
5098   </sect2>
5099  </sect1>
5100
5101
5102   <sect1 id="functions-formatting">
5103    <title>Data Type Formatting Functions</title>
5104
5105    <indexterm>
5106     <primary>formatting</primary>
5107    </indexterm>
5108
5109    <para>
5110     The <productname>PostgreSQL</productname> formatting functions
5111     provide a powerful set of tools for converting various data types
5112     (date/time, integer, floating point, numeric) to formatted strings
5113     and for converting from formatted strings to specific data types.
5114     <xref linkend="functions-formatting-table"> lists them.
5115     These functions all follow a common calling convention: the first
5116     argument is the value to be formatted and the second argument is a
5117     template that defines the output or input format.
5118    </para>
5119    <para>
5120     A single-argument <function>to_timestamp</function> function is also
5121     available;  it accepts a
5122     <type>double precision</type> argument and converts from Unix epoch
5123     (seconds since 1970-01-01 00:00:00+00) to
5124     <type>timestamp with time zone</type>.
5125     (<type>Integer</type> Unix epochs are implicitly cast to
5126     <type>double precision</type>.)
5127    </para>
5128
5129     <table id="functions-formatting-table">
5130      <title>Formatting Functions</title>
5131      <tgroup cols="4">
5132       <thead>
5133        <row>
5134         <entry>Function</entry>
5135         <entry>Return Type</entry>
5136         <entry>Description</entry>
5137         <entry>Example</entry>
5138        </row>
5139       </thead>
5140       <tbody>
5141        <row>
5142         <entry>
5143          <indexterm>
5144           <primary>to_char</primary>
5145          </indexterm>
5146          <literal><function>to_char(<type>timestamp</type>, <type>text</type>)</function></literal>
5147         </entry>
5148         <entry><type>text</type></entry>
5149         <entry>convert time stamp to string</entry>
5150         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
5151        </row>
5152        <row>
5153         <entry><literal><function>to_char(<type>interval</type>, <type>text</type>)</function></literal></entry>
5154         <entry><type>text</type></entry>
5155         <entry>convert interval to string</entry>
5156         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
5157        </row>
5158        <row>
5159         <entry><literal><function>to_char(<type>int</type>, <type>text</type>)</function></literal></entry>
5160         <entry><type>text</type></entry>
5161         <entry>convert integer to string</entry>
5162         <entry><literal>to_char(125, '999')</literal></entry>
5163        </row>
5164        <row>
5165         <entry><literal><function>to_char</function>(<type>double precision</type>,
5166         <type>text</type>)</literal></entry>
5167         <entry><type>text</type></entry>
5168         <entry>convert real/double precision to string</entry>
5169         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
5170        </row>
5171        <row>
5172         <entry><literal><function>to_char(<type>numeric</type>, <type>text</type>)</function></literal></entry>
5173         <entry><type>text</type></entry>
5174         <entry>convert numeric to string</entry>
5175         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
5176        </row>
5177        <row>
5178         <entry>
5179          <indexterm>
5180           <primary>to_date</primary>
5181          </indexterm>
5182          <literal><function>to_date(<type>text</type>, <type>text</type>)</function></literal>
5183         </entry>
5184         <entry><type>date</type></entry>
5185         <entry>convert string to date</entry>
5186         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5187        </row>
5188        <row>
5189         <entry>
5190          <indexterm>
5191           <primary>to_number</primary>
5192          </indexterm>
5193          <literal><function>to_number(<type>text</type>, <type>text</type>)</function></literal>
5194         </entry>
5195         <entry><type>numeric</type></entry>
5196         <entry>convert string to numeric</entry>
5197         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
5198        </row>
5199        <row>
5200         <entry>
5201          <indexterm>
5202           <primary>to_timestamp</primary>
5203          </indexterm>
5204          <literal><function>to_timestamp(<type>text</type>, <type>text</type>)</function></literal>
5205         </entry>
5206         <entry><type>timestamp with time zone</type></entry>
5207         <entry>convert string to time stamp</entry>
5208         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5209        </row>
5210        <row>
5211         <entry><literal><function>to_timestamp(<type>double precision</type>)</function></literal></entry>
5212         <entry><type>timestamp with time zone</type></entry>
5213         <entry>convert Unix epoch to time stamp</entry>
5214         <entry><literal>to_timestamp(1284352323)</literal></entry>
5215        </row>
5216       </tbody>
5217      </tgroup>
5218     </table>
5219
5220    <para>
5221     In a <function>to_char</> output template string, there are certain
5222     patterns that are recognized and replaced with appropriately-formatted
5223     data based on the given value.  Any text that is not a template pattern is
5224     simply copied verbatim.  Similarly, in an input template string (for the
5225     other functions), template patterns identify the values to be supplied by
5226     the input data string.
5227    </para>
5228
5229   <para>
5230    <xref linkend="functions-formatting-datetime-table"> shows the
5231    template patterns available for formatting date and time values.
5232   </para>
5233
5234     <table id="functions-formatting-datetime-table">
5235      <title>Template Patterns for Date/Time Formatting</title>
5236      <tgroup cols="2">
5237       <thead>
5238        <row>
5239         <entry>Pattern</entry>
5240         <entry>Description</entry>
5241        </row>
5242       </thead>
5243       <tbody>
5244        <row>
5245         <entry><literal>HH</literal></entry>
5246         <entry>hour of day (01-12)</entry>
5247        </row>
5248        <row>
5249         <entry><literal>HH12</literal></entry>
5250         <entry>hour of day (01-12)</entry>
5251        </row>
5252        <row>
5253         <entry><literal>HH24</literal></entry>
5254         <entry>hour of day (00-23)</entry>
5255        </row>
5256        <row>
5257         <entry><literal>MI</literal></entry>
5258         <entry>minute (00-59)</entry>
5259        </row>
5260        <row>
5261         <entry><literal>SS</literal></entry>
5262         <entry>second (00-59)</entry>
5263        </row>
5264        <row>
5265         <entry><literal>MS</literal></entry>
5266         <entry>millisecond (000-999)</entry>
5267        </row>
5268        <row>
5269         <entry><literal>US</literal></entry>
5270         <entry>microsecond (000000-999999)</entry>
5271        </row>
5272        <row>
5273         <entry><literal>SSSS</literal></entry>
5274         <entry>seconds past midnight (0-86399)</entry>
5275        </row>
5276        <row>
5277         <entry><literal>AM</literal>, <literal>am</literal>,
5278         <literal>PM</literal> or <literal>pm</literal></entry>
5279         <entry>meridiem indicator (without periods)</entry>
5280        </row>
5281        <row>
5282         <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
5283         <literal>P.M.</literal> or <literal>p.m.</literal></entry>
5284         <entry>meridiem indicator (with periods)</entry>
5285        </row>
5286        <row>
5287         <entry><literal>Y,YYY</literal></entry>
5288         <entry>year (4 and more digits) with comma</entry>
5289        </row>
5290        <row>
5291         <entry><literal>YYYY</literal></entry>
5292         <entry>year (4 and more digits)</entry>
5293        </row>
5294        <row>
5295         <entry><literal>YYY</literal></entry>
5296         <entry>last 3 digits of year</entry>
5297        </row>
5298        <row>
5299         <entry><literal>YY</literal></entry>
5300         <entry>last 2 digits of year</entry>
5301        </row>
5302        <row>
5303         <entry><literal>Y</literal></entry>
5304         <entry>last digit of year</entry>
5305        </row>
5306        <row>
5307         <entry><literal>IYYY</literal></entry>
5308         <entry>ISO year (4 and more digits)</entry>
5309        </row>
5310        <row>
5311         <entry><literal>IYY</literal></entry>
5312         <entry>last 3 digits of ISO year</entry>
5313        </row>
5314        <row>
5315         <entry><literal>IY</literal></entry>
5316         <entry>last 2 digits of ISO year</entry>
5317        </row>
5318        <row>
5319         <entry><literal>I</literal></entry>
5320         <entry>last digit of ISO year</entry>
5321        </row>
5322        <row>
5323         <entry><literal>BC</literal>, <literal>bc</literal>,
5324         <literal>AD</literal> or <literal>ad</literal></entry>
5325         <entry>era indicator (without periods)</entry>
5326        </row>
5327        <row>
5328         <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
5329         <literal>A.D.</literal> or <literal>a.d.</literal></entry>
5330         <entry>era indicator (with periods)</entry>
5331        </row>
5332        <row>
5333         <entry><literal>MONTH</literal></entry>
5334         <entry>full upper case month name (blank-padded to 9 chars)</entry>
5335        </row>
5336        <row>
5337         <entry><literal>Month</literal></entry>
5338         <entry>full capitalized month name (blank-padded to 9 chars)</entry>
5339        </row>
5340        <row>
5341         <entry><literal>month</literal></entry>
5342         <entry>full lower case month name (blank-padded to 9 chars)</entry>
5343        </row>
5344        <row>
5345         <entry><literal>MON</literal></entry>
5346         <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
5347        </row>
5348        <row>
5349         <entry><literal>Mon</literal></entry>
5350         <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
5351        </row>
5352        <row>
5353         <entry><literal>mon</literal></entry>
5354         <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
5355        </row>
5356        <row>
5357         <entry><literal>MM</literal></entry>
5358         <entry>month number (01-12)</entry>
5359        </row>
5360        <row>
5361         <entry><literal>DAY</literal></entry>
5362         <entry>full upper case day name (blank-padded to 9 chars)</entry>
5363        </row>
5364        <row>
5365         <entry><literal>Day</literal></entry>
5366         <entry>full capitalized day name (blank-padded to 9 chars)</entry>
5367        </row>
5368        <row>
5369         <entry><literal>day</literal></entry>
5370         <entry>full lower case day name (blank-padded to 9 chars)</entry>
5371        </row>
5372        <row>
5373         <entry><literal>DY</literal></entry>
5374         <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
5375        </row>
5376        <row>
5377         <entry><literal>Dy</literal></entry>
5378         <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
5379        </row>
5380        <row>
5381         <entry><literal>dy</literal></entry>
5382         <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
5383        </row>
5384        <row>
5385         <entry><literal>DDD</literal></entry>
5386         <entry>day of year (001-366)</entry>
5387        </row>
5388        <row>
5389         <entry><literal>IDDD</literal></entry>
5390         <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
5391        </row>
5392        <row>
5393         <entry><literal>DD</literal></entry>
5394         <entry>day of month (01-31)</entry>
5395        </row>
5396        <row>
5397         <entry><literal>D</literal></entry>
5398         <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
5399        </row>
5400        <row>
5401         <entry><literal>ID</literal></entry>
5402         <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
5403        </row>
5404        <row>
5405         <entry><literal>W</literal></entry>
5406         <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
5407        </row>
5408        <row>
5409         <entry><literal>WW</literal></entry>
5410         <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
5411        </row>
5412        <row>
5413         <entry><literal>IW</literal></entry>
5414         <entry>ISO week number of year (01 - 53; the first Thursday of the new year is in week 1.)</entry>
5415        </row>
5416        <row>
5417         <entry><literal>CC</literal></entry>
5418         <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
5419        </row>
5420        <row>
5421         <entry><literal>J</literal></entry>
5422         <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
5423        </row>
5424        <row>
5425         <entry><literal>Q</literal></entry>
5426         <entry>quarter (ignored by <function>to_date</> and <function>to_timestamp</>)</entry>
5427        </row>
5428        <row>
5429         <entry><literal>RM</literal></entry>
5430         <entry>month in upper case Roman numerals (I-XII; I=January)</entry>
5431        </row>
5432        <row>
5433         <entry><literal>rm</literal></entry>
5434         <entry>month in lower case Roman numerals (i-xii; i=January)</entry>
5435        </row>
5436        <row>
5437         <entry><literal>TZ</literal></entry>
5438         <entry>upper case time-zone name</entry>
5439        </row>
5440        <row>
5441         <entry><literal>tz</literal></entry>
5442         <entry>lower case time-zone name</entry>
5443        </row>
5444       </tbody>
5445      </tgroup>
5446     </table>
5447
5448    <para>
5449     Modifiers can be applied to any template pattern to alter its
5450     behavior.  For example, <literal>FMMonth</literal>
5451     is the <literal>Month</literal> pattern with the
5452     <literal>FM</literal> modifier.
5453     <xref linkend="functions-formatting-datetimemod-table"> shows the
5454     modifier patterns for date/time formatting.
5455    </para>
5456
5457     <table id="functions-formatting-datetimemod-table">
5458      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5459      <tgroup cols="3">
5460       <thead>
5461        <row>
5462         <entry>Modifier</entry>
5463         <entry>Description</entry>
5464         <entry>Example</entry>
5465        </row>
5466       </thead>
5467       <tbody>
5468        <row>
5469         <entry><literal>FM</literal> prefix</entry>
5470         <entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
5471         <entry><literal>FMMonth</literal></entry>
5472        </row>
5473        <row>
5474         <entry><literal>TH</literal> suffix</entry>
5475         <entry>upper case ordinal number suffix</entry>
5476         <entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
5477        </row>
5478        <row>
5479         <entry><literal>th</literal> suffix</entry>
5480         <entry>lower case ordinal number suffix</entry>
5481         <entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
5482        </row>
5483        <row>
5484         <entry><literal>FX</literal> prefix</entry>
5485         <entry>fixed format global option (see usage notes)</entry>
5486         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5487        </row>
5488        <row>
5489         <entry><literal>TM</literal> prefix</entry>
5490         <entry>translation mode (print localized day and month names based on
5491          <xref linkend="guc-lc-time">)</entry>
5492         <entry><literal>TMMonth</literal></entry>
5493        </row>
5494        <row>
5495         <entry><literal>SP</literal> suffix</entry>
5496         <entry>spell mode (not implemented)</entry>
5497         <entry><literal>DDSP</literal></entry>
5498        </row>
5499       </tbody>
5500      </tgroup>
5501     </table>
5502
5503    <para>
5504     Usage notes for date/time formatting:
5505
5506     <itemizedlist>
5507      <listitem>
5508       <para>
5509        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5510        that would otherwise be added to make the output of a pattern be
5511        fixed-width.  In <productname>PostgreSQL</productname>,
5512        <literal>FM</literal> modifies only the next specification, while in
5513        Oracle <literal>FM</literal> affects all subsequent
5514        specifications, and repeated <literal>FM</literal> modifiers
5515        toggle fill mode on and off.
5516       </para>
5517      </listitem>
5518
5519      <listitem>
5520       <para>
5521        <literal>TM</literal> does not include trailing blanks.
5522       </para>
5523      </listitem>
5524
5525      <listitem>
5526       <para>
5527        <function>to_timestamp</function> and <function>to_date</function>
5528        skip multiple blank spaces in the input string unless the
5529        <literal>FX</literal> option is used. For example,
5530        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> works, but
5531        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
5532        because <function>to_timestamp</function> expects one space only.
5533        <literal>FX</literal> must be specified as the first item in
5534        the template.
5535       </para>
5536      </listitem>
5537
5538      <listitem>
5539       <para>
5540        Ordinary text is allowed in <function>to_char</function>
5541        templates and will be output literally.  You can put a substring
5542        in double quotes to force it to be interpreted as literal text
5543        even if it contains pattern key words.  For example, in
5544        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5545        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5546        will not be.  In <function>to_date</>, <function>to_number</>,
5547        and <function>to_timestamp</>, double-quoted strings skip the number of
5548        input characters contained in the string, e.g. <literal>"XX"</>
5549        skips two input characters.
5550       </para>
5551      </listitem>
5552
5553      <listitem>
5554       <para>
5555        If you want to have a double quote in the output you must
5556        precede it with a backslash, for example <literal>'\"YYYY
5557        Month\"'</literal>. <!-- "" font-lock sanity :-) -->
5558       </para>
5559      </listitem>
5560
5561      <listitem>
5562       <para>
5563        If the year format specification is less than four digits, e.g.
5564        <literal>YYY</>, and the supplied year is less than four digits,
5565        the year will be adjusted to be nearest to the year 2020, e.g.
5566        <literal>95</> becomes 1995.
5567       </para>
5568      </listitem>
5569
5570      <listitem>
5571       <para>
5572        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5573        <type>date</type> has a restriction when processing years with more than 4 digits. You must
5574        use some non-digit character or template after <literal>YYYY</literal>,
5575        otherwise the year is always interpreted as 4 digits. For example
5576        (with the year 20000):
5577        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
5578        interpreted as a 4-digit year; instead use a non-digit
5579        separator after the year, like
5580        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5581        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5582       </para>
5583      </listitem>
5584
5585      <listitem>
5586       <para>
5587        In conversions from string to <type>timestamp</type> or
5588        <type>date</type>, the <literal>CC</literal> (century) field is ignored
5589        if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
5590        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5591        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5592        as the year in the specified century.  If the century is
5593        specified but the year is not, the first year of the century
5594        is assumed.
5595       </para>
5596      </listitem>
5597
5598      <listitem>
5599       <para>
5600        An ISO week date (as distinct from a Gregorian date) can be
5601        specified to <function>to_timestamp</function> and
5602        <function>to_date</function> in one of two ways:
5603        <itemizedlist>
5604         <listitem>
5605          <para>
5606           Year, week, and weekday:  for example <literal>to_date('2006-42-4',
5607           'IYYY-IW-ID')</literal> returns the date
5608           <literal>2006-10-19</literal>.  If you omit the weekday it
5609           is assumed to be 1 (Monday).
5610          </para>
5611         </listitem>
5612         <listitem>
5613          <para>
5614           Year and day of year:  for example <literal>to_date('2006-291',
5615           'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5616          </para>
5617         </listitem>
5618        </itemizedlist>
5619       </para>
5620       <para>
5621        Attempting to construct a date using a mixture of ISO week and
5622        Gregorian date fields is nonsensical, and will cause an error.  In the
5623        context of an ISO year, the concept of a <quote>month</> or <quote>day
5624        of month</> has no meaning.  In the context of a Gregorian year, the
5625        ISO week has no meaning.  Users should avoid mixing Gregorian and
5626        ISO date specifications.
5627       </para>
5628      </listitem>
5629
5630      <listitem>
5631       <para>
5632        In a conversion from string to <type>timestamp</type>, millisecond
5633        (<literal>MS</literal>) or microsecond (<literal>US</literal>)
5634        values are used as the
5635        seconds digits after the decimal point. For example
5636        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5637        but 300, because the conversion counts it as 12 + 0.3 seconds.
5638        This means for the format <literal>SS:MS</literal>, the input values
5639        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5640        same number of milliseconds. To get three milliseconds, one must use
5641        <literal>12:003</literal>, which the conversion counts as
5642        12 + 0.003 = 12.003 seconds.
5643       </para>
5644
5645       <para>
5646        Here is a more
5647        complex example:
5648        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5649        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5650        1230 microseconds = 2.021230 seconds.
5651       </para>
5652      </listitem>
5653
5654      <listitem>
5655       <para>
5656         <function>to_char(..., 'ID')</function>'s day of the week numbering
5657         matches the <function>extract(isodow from ...)</function> function, but
5658         <function>to_char(..., 'D')</function>'s does not match
5659         <function>extract(dow from ...)</function>'s day numbering.
5660       </para>
5661      </listitem>
5662
5663      <listitem>
5664       <para>
5665         <function>to_char(interval)</function> formats <literal>HH</> and
5666         <literal>HH12</> as shown on a 12-hour clock, i.e. zero hours
5667         and 36 hours output as <literal>12</>, while <literal>HH24</>
5668         outputs the full hour value, which can exceed 23 for intervals.
5669       </para>
5670      </listitem>
5671
5672     </itemizedlist>
5673    </para>
5674
5675   <para>
5676    <xref linkend="functions-formatting-numeric-table"> shows the
5677    template patterns available for formatting numeric values.
5678   </para>
5679
5680     <table id="functions-formatting-numeric-table">
5681      <title>Template Patterns for Numeric Formatting</title>
5682      <tgroup cols="2">
5683       <thead>
5684        <row>
5685         <entry>Pattern</entry>
5686         <entry>Description</entry>
5687        </row>
5688       </thead>
5689       <tbody>
5690        <row>
5691         <entry><literal>9</literal></entry>
5692         <entry>value with the specified number of digits</entry>
5693        </row>
5694        <row>
5695         <entry><literal>0</literal></entry>
5696         <entry>value with leading zeros</entry>
5697        </row>
5698        <row>
5699         <entry><literal>.</literal> (period)</entry>
5700         <entry>decimal point</entry>
5701        </row>
5702        <row>
5703         <entry><literal>,</literal> (comma)</entry>
5704         <entry>group (thousand) separator</entry>
5705        </row>
5706        <row>
5707         <entry><literal>PR</literal></entry>
5708         <entry>negative value in angle brackets</entry>
5709        </row>
5710        <row>
5711         <entry><literal>S</literal></entry>
5712         <entry>sign anchored to number (uses locale)</entry>
5713        </row>
5714        <row>
5715         <entry><literal>L</literal></entry>
5716         <entry>currency symbol (uses locale)</entry>
5717        </row>
5718        <row>
5719         <entry><literal>D</literal></entry>
5720         <entry>decimal point (uses locale)</entry>
5721        </row>
5722        <row>
5723         <entry><literal>G</literal></entry>
5724         <entry>group separator (uses locale)</entry>
5725        </row>
5726        <row>
5727         <entry><literal>MI</literal></entry>
5728         <entry>minus sign in specified position (if number &lt; 0)</entry>
5729        </row>
5730        <row>
5731         <entry><literal>PL</literal></entry>
5732         <entry>plus sign in specified position (if number &gt; 0)</entry>
5733        </row>
5734        <row>
5735         <entry><literal>SG</literal></entry>
5736         <entry>plus/minus sign in specified position</entry>
5737        </row>
5738        <row>
5739         <entry><literal>RN</literal></entry>
5740         <entry>Roman numeral (input between 1 and 3999)</entry>
5741        </row>
5742        <row>
5743         <entry><literal>TH</literal> or <literal>th</literal></entry>
5744         <entry>ordinal number suffix</entry>
5745        </row>
5746        <row>
5747         <entry><literal>V</literal></entry>
5748         <entry>shift specified number of digits (see notes)</entry>
5749        </row>
5750        <row>
5751         <entry><literal>EEEE</literal></entry>
5752         <entry>exponent for scientific notation</entry>
5753        </row>
5754       </tbody>
5755      </tgroup>
5756     </table>
5757
5758    <para>
5759     Usage notes for numeric formatting:
5760
5761     <itemizedlist>
5762      <listitem>
5763       <para>
5764        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5765        <literal>MI</literal> is not anchored to
5766        the number; for example,
5767        <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
5768        but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
5769        The Oracle implementation does not allow the use of
5770        <literal>MI</literal> before <literal>9</literal>, but rather
5771        requires that <literal>9</literal> precede
5772        <literal>MI</literal>.
5773       </para>
5774      </listitem>
5775
5776      <listitem>
5777       <para>
5778        <literal>9</literal> results in a value with the same number of
5779        digits as there are <literal>9</literal>s. If a digit is
5780        not available it outputs a space.
5781       </para>
5782      </listitem>
5783
5784      <listitem>
5785       <para>
5786        <literal>TH</literal> does not convert values less than zero
5787        and does not convert fractional numbers.
5788       </para>
5789      </listitem>
5790
5791      <listitem>
5792       <para>
5793        <literal>PL</literal>, <literal>SG</literal>, and
5794        <literal>TH</literal> are <productname>PostgreSQL</productname>
5795        extensions.
5796       </para>
5797      </listitem>
5798
5799      <listitem>
5800       <para>
5801        <literal>V</literal> effectively
5802        multiplies the input values by
5803        <literal>10^<replaceable>n</replaceable></literal>, where
5804        <replaceable>n</replaceable> is the number of digits following
5805        <literal>V</literal>.
5806        <function>to_char</function> does not support the use of
5807        <literal>V</literal> combined with a decimal point
5808        (e.g., <literal>99.9V99</literal> is not allowed).
5809       </para>
5810      </listitem>
5811
5812      <listitem>
5813       <para>
5814        <literal>EEEE</literal> (scientific notation) cannot be used in
5815        combination with any of the other formatting patterns or
5816        modifiers other than digit and decimal point patterns, and must be at the end of the format string
5817        (e.g., <literal>9.99EEEE</literal> is a valid pattern).
5818       </para>
5819      </listitem>
5820     </itemizedlist>
5821    </para>
5822
5823    <para>
5824     Certain modifiers can be applied to any template pattern to alter its
5825     behavior.  For example, <literal>FM9999</literal>
5826     is the <literal>9999</literal> pattern with the
5827     <literal>FM</literal> modifier.
5828     <xref linkend="functions-formatting-numericmod-table"> shows the
5829     modifier patterns for numeric formatting.
5830    </para>
5831
5832     <table id="functions-formatting-numericmod-table">
5833      <title>Template Pattern Modifiers for Numeric Formatting</title>
5834      <tgroup cols="3">
5835       <thead>
5836        <row>
5837         <entry>Modifier</entry>
5838         <entry>Description</entry>
5839         <entry>Example</entry>
5840        </row>
5841       </thead>
5842       <tbody>
5843        <row>
5844         <entry><literal>FM</literal> prefix</entry>
5845         <entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
5846         <entry><literal>FM9999</literal></entry>
5847        </row>
5848        <row>
5849         <entry><literal>TH</literal> suffix</entry>
5850         <entry>upper case ordinal number suffix</entry>
5851         <entry><literal>999TH</literal></entry>
5852        </row>
5853        <row>
5854         <entry><literal>th</literal> suffix</entry>
5855         <entry>lower case ordinal number suffix</entry>
5856         <entry><literal>999th</literal></entry>
5857        </row>
5858       </tbody>
5859      </tgroup>
5860     </table>
5861
5862   <para>
5863    <xref linkend="functions-formatting-examples-table"> shows some
5864    examples of the use of the <function>to_char</function> function.
5865   </para>
5866
5867     <table id="functions-formatting-examples-table">
5868      <title><function>to_char</function> Examples</title>
5869      <tgroup cols="2">
5870       <thead>
5871        <row>
5872         <entry>Expression</entry>
5873         <entry>Result</entry>
5874        </row>
5875       </thead>
5876       <tbody>
5877        <row>
5878         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5879         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
5880        </row>
5881        <row>
5882         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5883         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
5884        </row>
5885        <row>
5886         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5887         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
5888        </row>
5889        <row>
5890         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5891         <entry><literal>'-.1'</literal></entry>
5892        </row>
5893        <row>
5894         <entry><literal>to_char(0.1, '0.9')</literal></entry>
5895         <entry><literal>'&nbsp;0.1'</literal></entry>
5896        </row>
5897        <row>
5898         <entry><literal>to_char(12, '9990999.9')</literal></entry>
5899         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
5900        </row>
5901        <row>
5902         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5903         <entry><literal>'0012.'</literal></entry>
5904        </row>
5905        <row>
5906         <entry><literal>to_char(485, '999')</literal></entry>
5907         <entry><literal>'&nbsp;485'</literal></entry>
5908        </row>
5909        <row>
5910         <entry><literal>to_char(-485, '999')</literal></entry>
5911         <entry><literal>'-485'</literal></entry>
5912        </row>
5913        <row>
5914         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
5915         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
5916        </row>
5917        <row>
5918         <entry><literal>to_char(1485, '9,999')</literal></entry>
5919         <entry><literal>'&nbsp;1,485'</literal></entry>
5920        </row>
5921        <row>
5922         <entry><literal>to_char(1485, '9G999')</literal></entry>
5923         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
5924        </row>
5925        <row>
5926         <entry><literal>to_char(148.5, '999.999')</literal></entry>
5927         <entry><literal>'&nbsp;148.500'</literal></entry>
5928        </row>
5929        <row>
5930         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5931         <entry><literal>'148.5'</literal></entry>
5932        </row>
5933        <row>
5934         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5935         <entry><literal>'148.500'</literal></entry>
5936        </row>
5937        <row>
5938         <entry><literal>to_char(148.5, '999D999')</literal></entry>
5939         <entry><literal>'&nbsp;148,500'</literal></entry>
5940        </row>
5941        <row>
5942         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5943         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
5944        </row>
5945        <row>
5946         <entry><literal>to_char(-485, '999S')</literal></entry>
5947         <entry><literal>'485-'</literal></entry>
5948        </row>
5949        <row>
5950         <entry><literal>to_char(-485, '999MI')</literal></entry>
5951         <entry><literal>'485-'</literal></entry>
5952        </row>
5953        <row>
5954         <entry><literal>to_char(485, '999MI')</literal></entry>
5955         <entry><literal>'485&nbsp;'</literal></entry>
5956        </row>
5957        <row>
5958         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5959         <entry><literal>'485'</literal></entry>
5960        </row>
5961        <row>
5962         <entry><literal>to_char(485, 'PL999')</literal></entry>
5963         <entry><literal>'+485'</literal></entry>
5964        </row>
5965        <row>
5966         <entry><literal>to_char(485, 'SG999')</literal></entry>
5967         <entry><literal>'+485'</literal></entry>
5968        </row>
5969        <row>
5970         <entry><literal>to_char(-485, 'SG999')</literal></entry>
5971         <entry><literal>'-485'</literal></entry>
5972        </row>
5973        <row>
5974         <entry><literal>to_char(-485, '9SG99')</literal></entry>
5975         <entry><literal>'4-85'</literal></entry>
5976        </row>
5977        <row>
5978         <entry><literal>to_char(-485, '999PR')</literal></entry>
5979         <entry><literal>'&lt;485&gt;'</literal></entry>
5980        </row>
5981        <row>
5982         <entry><literal>to_char(485, 'L999')</literal></entry>
5983         <entry><literal>'DM&nbsp;485</literal></entry>
5984        </row>
5985        <row>
5986         <entry><literal>to_char(485, 'RN')</literal></entry>
5987         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
5988        </row>
5989        <row>
5990         <entry><literal>to_char(485, 'FMRN')</literal></entry>
5991         <entry><literal>'CDLXXXV'</literal></entry>
5992        </row>
5993        <row>
5994         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5995         <entry><literal>'V'</literal></entry>
5996        </row>
5997        <row>
5998         <entry><literal>to_char(482, '999th')</literal></entry>
5999         <entry><literal>'&nbsp;482nd'</literal></entry>
6000        </row>
6001        <row>
6002         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
6003         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
6004        </row>
6005        <row>
6006         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
6007         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
6008        </row>
6009        <row>
6010         <entry><literal>to_char(12, '99V999')</literal></entry>
6011         <entry><literal>'&nbsp;12000'</literal></entry>
6012        </row>
6013        <row>
6014         <entry><literal>to_char(12.4, '99V999')</literal></entry>
6015         <entry><literal>'&nbsp;12400'</literal></entry>
6016        </row>
6017        <row>
6018         <entry><literal>to_char(12.45, '99V9')</literal></entry>
6019         <entry><literal>'&nbsp;125'</literal></entry>
6020        </row>
6021        <row>
6022         <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
6023         <entry><literal>' 4.86e-04'</literal></entry>
6024        </row>
6025       </tbody>
6026      </tgroup>
6027     </table>
6028
6029   </sect1>
6030
6031
6032   <sect1 id="functions-datetime">
6033    <title>Date/Time Functions and Operators</title>
6034
6035   <para>
6036    <xref linkend="functions-datetime-table"> shows the available
6037    functions for date/time value processing, with details appearing in
6038    the following subsections.  <xref
6039    linkend="operators-datetime-table"> illustrates the behaviors of
6040    the basic arithmetic operators (<literal>+</literal>,
6041    <literal>*</literal>, etc.).  For formatting functions, refer to
6042    <xref linkend="functions-formatting">.  You should be familiar with
6043    the background information on date/time data types from <xref
6044    linkend="datatype-datetime">.
6045   </para>
6046
6047   <para>
6048    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
6049    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
6050    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
6051    For brevity, these variants are not shown separately.  Also, the
6052    <literal>+</> and <literal>*</> operators come in commutative pairs (for
6053    example both date + integer and integer + date); we show only one of each
6054    such pair.
6055   </para>
6056
6057     <table id="operators-datetime-table">
6058      <title>Date/Time Operators</title>
6059
6060      <tgroup cols="3">
6061       <thead>
6062        <row>
6063         <entry>Operator</entry>
6064         <entry>Example</entry>
6065         <entry>Result</entry>
6066        </row>
6067       </thead>
6068
6069       <tbody>
6070        <row>
6071         <entry> <literal>+</literal> </entry>
6072         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
6073         <entry><literal>date '2001-10-05'</literal></entry>
6074        </row>
6075
6076        <row>
6077         <entry> <literal>+</literal> </entry>
6078         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
6079         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
6080        </row>
6081
6082        <row>
6083         <entry> <literal>+</literal> </entry>
6084         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
6085         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
6086        </row>
6087
6088        <row>
6089         <entry> <literal>+</literal> </entry>
6090         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
6091         <entry><literal>interval '1 day 01:00:00'</literal></entry>
6092        </row>
6093
6094        <row>
6095         <entry> <literal>+</literal> </entry>
6096         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
6097         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
6098        </row>
6099
6100        <row>
6101         <entry> <literal>+</literal> </entry>
6102         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
6103         <entry><literal>time '04:00:00'</literal></entry>
6104        </row>
6105
6106        <row>
6107         <entry> <literal>-</literal> </entry>
6108         <entry><literal>- interval '23 hours'</literal></entry>
6109         <entry><literal>interval '-23:00:00'</literal></entry>
6110        </row>
6111
6112        <row>
6113         <entry> <literal>-</literal> </entry>
6114         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
6115         <entry><literal>integer '3'</literal> (days)</entry>
6116        </row>
6117
6118        <row>
6119         <entry> <literal>-</literal> </entry>
6120         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
6121         <entry><literal>date '2001-09-24'</literal></entry>
6122        </row>
6123
6124        <row>
6125         <entry> <literal>-</literal> </entry>
6126         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
6127         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
6128        </row>
6129
6130        <row>
6131         <entry> <literal>-</literal> </entry>
6132         <entry><literal>time '05:00' - time '03:00'</literal></entry>
6133         <entry><literal>interval '02:00:00'</literal></entry>
6134        </row>
6135
6136        <row>
6137         <entry> <literal>-</literal> </entry>
6138         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
6139         <entry><literal>time '03:00:00'</literal></entry>
6140        </row>
6141
6142        <row>
6143         <entry> <literal>-</literal> </entry>
6144         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
6145         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
6146        </row>
6147
6148        <row>
6149         <entry> <literal>-</literal> </entry>
6150         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
6151         <entry><literal>interval '1 day -01:00:00'</literal></entry>
6152        </row>
6153
6154        <row>
6155         <entry> <literal>-</literal> </entry>
6156         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
6157         <entry><literal>interval '1 day 15:00:00'</literal></entry>
6158        </row>
6159
6160        <row>
6161         <entry> <literal>*</literal> </entry>
6162         <entry><literal>900 * interval '1 second'</literal></entry>
6163         <entry><literal>interval '00:15:00'</literal></entry>
6164        </row>
6165
6166        <row>
6167         <entry> <literal>*</literal> </entry>
6168         <entry><literal>21 * interval '1 day'</literal></entry>
6169         <entry><literal>interval '21 days'</literal></entry>
6170        </row>
6171
6172        <row>
6173         <entry> <literal>*</literal> </entry>
6174         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
6175         <entry><literal>interval '03:30:00'</literal></entry>
6176        </row>
6177
6178        <row>
6179         <entry> <literal>/</literal> </entry>
6180         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
6181         <entry><literal>interval '00:40:00'</literal></entry>
6182        </row>
6183       </tbody>
6184      </tgroup>
6185     </table>
6186
6187     <table id="functions-datetime-table">
6188      <title>Date/Time Functions</title>
6189      <tgroup cols="5">
6190       <thead>
6191        <row>
6192         <entry>Function</entry>
6193         <entry>Return Type</entry>
6194         <entry>Description</entry>
6195         <entry>Example</entry>
6196         <entry>Result</entry>
6197        </row>
6198       </thead>
6199
6200       <tbody>
6201        <row>
6202         <entry>
6203          <indexterm>
6204           <primary>age</primary>
6205          </indexterm>
6206          <literal><function>age(<type>timestamp</type>, <type>timestamp</type>)</function></literal>
6207         </entry>
6208         <entry><type>interval</type></entry>
6209         <entry>Subtract arguments, producing a <quote>symbolic</> result that
6210         uses years and months</entry>
6211         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
6212         <entry><literal>43 years 9 mons 27 days</literal></entry>
6213        </row>
6214
6215        <row>
6216         <entry><literal><function>age(<type>timestamp</type>)</function></literal></entry>
6217         <entry><type>interval</type></entry>
6218         <entry>Subtract from <function>current_date</function> (at midnight)</entry>
6219         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
6220         <entry><literal>43 years 8 mons 3 days</literal></entry>
6221        </row>
6222
6223        <row>
6224         <entry>
6225          <indexterm>
6226           <primary>clock_timestamp</primary>
6227          </indexterm>
6228          <literal><function>clock_timestamp()</function></literal>
6229         </entry>
6230         <entry><type>timestamp with time zone</type></entry>
6231         <entry>Current date and time (changes during statement execution);
6232          see <xref linkend="functions-datetime-current">
6233         </entry>
6234         <entry></entry>
6235         <entry></entry>
6236        </row>
6237
6238        <row>
6239         <entry>
6240          <indexterm>
6241           <primary>current_date</primary>
6242          </indexterm>
6243          <literal><function>current_date</function></literal>
6244         </entry>
6245         <entry><type>date</type></entry>
6246         <entry>Current date;
6247          see <xref linkend="functions-datetime-current">
6248         </entry>
6249         <entry></entry>
6250         <entry></entry>
6251        </row>
6252
6253        <row>
6254         <entry>
6255          <indexterm>
6256           <primary>current_time</primary>
6257          </indexterm>
6258          <literal><function>current_time</function></literal>
6259         </entry>
6260         <entry><type>time with time zone</type></entry>
6261         <entry>Current time of day;
6262          see <xref linkend="functions-datetime-current">
6263         </entry>
6264         <entry></entry>
6265         <entry></entry>
6266        </row>
6267
6268        <row>
6269         <entry>
6270          <indexterm>
6271           <primary>current_timestamp</primary>
6272          </indexterm>
6273          <literal><function>current_timestamp</function></literal>
6274         </entry>
6275         <entry><type>timestamp with time zone</type></entry>
6276         <entry>Current date and time (start of current transaction);
6277          see <xref linkend="functions-datetime-current">
6278         </entry>
6279         <entry></entry>
6280         <entry></entry>
6281        </row>
6282
6283        <row>
6284         <entry>
6285          <indexterm>
6286           <primary>date_part</primary>
6287          </indexterm>
6288          <literal><function>date_part(<type>text</type>, <type>timestamp</type>)</function></literal>
6289         </entry>
6290         <entry><type>double precision</type></entry>
6291         <entry>Get subfield (equivalent to <function>extract</function>);
6292          see <xref linkend="functions-datetime-extract">
6293         </entry>
6294         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6295         <entry><literal>20</literal></entry>
6296        </row>
6297
6298        <row>
6299         <entry><literal><function>date_part(<type>text</type>, <type>interval</type>)</function></literal></entry>
6300         <entry><type>double precision</type></entry>
6301         <entry>Get subfield (equivalent to
6302          <function>extract</function>); see <xref linkend="functions-datetime-extract">
6303         </entry>
6304         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
6305         <entry><literal>3</literal></entry>
6306        </row>
6307
6308        <row>
6309         <entry>
6310          <indexterm>
6311           <primary>date_trunc</primary>
6312          </indexterm>
6313          <literal><function>date_trunc(<type>text</type>, <type>timestamp</type>)</function></literal>
6314         </entry>
6315         <entry><type>timestamp</type></entry>
6316         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
6317         </entry>
6318         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6319         <entry><literal>2001-02-16 20:00:00</literal></entry>
6320        </row>
6321
6322        <row>
6323         <entry>
6324          <indexterm>
6325           <primary>extract</primary>
6326          </indexterm>
6327          <literal><function>extract</function>(<parameter>field</parameter> from
6328          <type>timestamp</type>)</literal>
6329         </entry>
6330         <entry><type>double precision</type></entry>
6331         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6332         </entry>
6333         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
6334         <entry><literal>20</literal></entry>
6335        </row>
6336
6337        <row>
6338         <entry><literal><function>extract</function>(<parameter>field</parameter> from
6339          <type>interval</type>)</literal></entry>
6340         <entry><type>double precision</type></entry>
6341         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6342         </entry>
6343         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
6344         <entry><literal>3</literal></entry>
6345        </row>
6346
6347        <row>
6348         <entry>
6349          <indexterm>
6350           <primary>isfinite</primary>
6351          </indexterm>
6352          <literal><function>isfinite(<type>date</type>)</function></literal>
6353         </entry>
6354         <entry><type>boolean</type></entry>
6355         <entry>Test for finite date (not +/-infinity)</entry>
6356         <entry><literal>isfinite(date '2001-02-16')</literal></entry>
6357         <entry><literal>true</literal></entry>
6358        </row>
6359
6360        <row>
6361         <entry><literal><function>isfinite(<type>timestamp</type>)</function></literal></entry>
6362         <entry><type>boolean</type></entry>
6363         <entry>Test for finite time stamp (not +/-infinity)</entry>
6364         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
6365         <entry><literal>true</literal></entry>
6366        </row>
6367
6368        <row>
6369         <entry><literal><function>isfinite(<type>interval</type>)</function></literal></entry>
6370         <entry><type>boolean</type></entry>
6371         <entry>Test for finite interval</entry>
6372         <entry><literal>isfinite(interval '4 hours')</literal></entry>
6373         <entry><literal>true</literal></entry>
6374        </row>
6375
6376        <row>
6377         <entry>
6378          <indexterm>
6379           <primary>justify_days</primary>
6380          </indexterm>
6381          <literal><function>justify_days(<type>interval</type>)</function></literal>
6382         </entry>
6383         <entry><type>interval</type></entry>
6384         <entry>Adjust interval so 30-day time periods are represented as months</entry>
6385         <entry><literal>justify_days(interval '35 days')</literal></entry>
6386         <entry><literal>1 mon 5 days</literal></entry>
6387        </row>
6388
6389        <row>
6390         <entry>
6391          <indexterm>
6392           <primary>justify_hours</primary>
6393          </indexterm>
6394          <literal><function>justify_hours(<type>interval</type>)</function></literal>
6395         </entry>
6396         <entry><type>interval</type></entry>
6397         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
6398         <entry><literal>justify_hours(interval '27 hours')</literal></entry>
6399         <entry><literal>1 day 03:00:00</literal></entry>
6400        </row>
6401
6402        <row>
6403         <entry>
6404          <indexterm>
6405           <primary>justify_interval</primary>
6406          </indexterm>
6407          <literal><function>justify_interval(<type>interval</type>)</function></literal>
6408         </entry>
6409         <entry><type>interval</type></entry>
6410         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
6411         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
6412         <entry><literal>29 days 23:00:00</literal></entry>
6413        </row>
6414
6415        <row>
6416         <entry>
6417          <indexterm>
6418           <primary>localtime</primary>
6419          </indexterm>
6420          <literal><function>localtime</function></literal>
6421         </entry>
6422         <entry><type>time</type></entry>
6423         <entry>Current time of day;
6424          see <xref linkend="functions-datetime-current">
6425         </entry>
6426         <entry></entry>
6427         <entry></entry>
6428        </row>
6429
6430        <row>
6431         <entry>
6432          <indexterm>
6433           <primary>localtimestamp</primary>
6434          </indexterm>
6435          <literal><function>localtimestamp</function></literal>
6436         </entry>
6437         <entry><type>timestamp</type></entry>
6438         <entry>Current date and time (start of current transaction);
6439          see <xref linkend="functions-datetime-current">
6440         </entry>
6441         <entry></entry>
6442         <entry></entry>
6443        </row>
6444
6445        <row>
6446         <entry>
6447          <indexterm>
6448           <primary>now</primary>
6449          </indexterm>
6450          <literal><function>now()</function></literal>
6451         </entry>
6452         <entry><type>timestamp with time zone</type></entry>
6453         <entry>Current date and time (start of current transaction);
6454          see <xref linkend="functions-datetime-current">
6455         </entry>
6456         <entry></entry>
6457         <entry></entry>
6458        </row>
6459
6460        <row>
6461         <entry>
6462          <indexterm>
6463           <primary>statement_timestamp</primary>
6464          </indexterm>
6465          <literal><function>statement_timestamp()</function></literal>
6466         </entry>
6467         <entry><type>timestamp with time zone</type></entry>
6468         <entry>Current date and time (start of current statement);
6469          see <xref linkend="functions-datetime-current">
6470         </entry>
6471         <entry></entry>
6472         <entry></entry>
6473        </row>
6474
6475        <row>
6476         <entry>
6477          <indexterm>
6478           <primary>timeofday</primary>
6479          </indexterm>
6480          <literal><function>timeofday()</function></literal>
6481         </entry>
6482         <entry><type>text</type></entry>
6483         <entry>Current date and time
6484          (like <function>clock_timestamp</>, but as a <type>text</> string);
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>transaction_timestamp</primary>
6495          </indexterm>
6496          <literal><function>transaction_timestamp()</function></literal>
6497         </entry>
6498         <entry><type>timestamp with time zone</type></entry>
6499         <entry>Current date and time (start of current transaction);
6500          see <xref linkend="functions-datetime-current">
6501         </entry>
6502         <entry></entry>
6503         <entry></entry>
6504        </row>
6505       </tbody>
6506      </tgroup>
6507     </table>
6508
6509    <para>
6510     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6511     supported:
6512 <synopsis>
6513 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6514 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6515 </synopsis>
6516     This expression yields true when two time periods (defined by their
6517     endpoints) overlap, false when they do not overlap.  The endpoints
6518     can be specified as pairs of dates, times, or time stamps; or as
6519     a date, time, or time stamp followed by an interval.  When a pair
6520     of values is provided, either the start or the end can be written
6521     first; <literal>OVERLAPS</> automatically takes the earlier value
6522     of the pair as the start.  Each time period is considered to
6523     represent the half-open interval <replaceable>start</> <literal>&lt;=</>
6524     <replaceable>time</> <literal>&lt;</> <replaceable>end</>, unless
6525     <replaceable>start</> and <replaceable>end</> are equal in which case it
6526     represents that single time instant.  This means for instance that two
6527     time periods with only an endpoint in common do not overlap.
6528    </para>
6529
6530 <screen>
6531 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6532        (DATE '2001-10-30', DATE '2002-10-30');
6533 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6534 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6535        (DATE '2001-10-30', DATE '2002-10-30');
6536 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6537 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
6538        (DATE '2001-10-30', DATE '2001-10-31');
6539 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6540 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
6541        (DATE '2001-10-30', DATE '2001-10-31');
6542 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6543 </screen>
6544
6545   <para>
6546    When adding an <type>interval</type> value to (or subtracting an
6547    <type>interval</type> value from) a <type>timestamp with time zone</type>
6548    value, the days component advances (or decrements) the date of the
6549    <type>timestamp with time zone</type> by the indicated number of days.
6550    Across daylight saving time changes (with the session time zone set to a
6551    time zone that recognizes DST), this means <literal>interval '1 day'</literal>
6552    does not necessarily equal <literal>interval '24 hours'</literal>.
6553    For example, with the session time zone set to <literal>CST7CDT</literal>,
6554    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
6555    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>,
6556    while adding <literal>interval '24 hours'</literal> to the same initial
6557    <type>timestamp with time zone</type> produces
6558    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6559    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone
6560    <literal>CST7CDT</literal>.
6561   </para>
6562
6563   <para>
6564    Note there can be ambiguity in the <literal>months</> returned by
6565    <function>age</> because different months have a different number of
6566    days.  <productname>PostgreSQL</>'s approach uses the month from the
6567    earlier of the two dates when calculating partial months.  For example,
6568    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6569    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6570    days</> because May has 31 days, while April has only 30.
6571   </para>
6572
6573   <sect2 id="functions-datetime-extract">
6574    <title><function>EXTRACT</function>, <function>date_part</function></title>
6575
6576    <indexterm>
6577     <primary>date_part</primary>
6578    </indexterm>
6579    <indexterm>
6580     <primary>extract</primary>
6581    </indexterm>
6582
6583 <synopsis>
6584 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6585 </synopsis>
6586
6587    <para>
6588     The <function>extract</function> function retrieves subfields
6589     such as year or hour from date/time values.
6590     <replaceable>source</replaceable> must be a value expression of
6591     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6592     (Expressions of type <type>date</type> are
6593     cast to <type>timestamp</type> and can therefore be used as
6594     well.)  <replaceable>field</replaceable> is an identifier or
6595     string that selects what field to extract from the source value.
6596     The <function>extract</function> function returns values of type
6597     <type>double precision</type>.
6598     The following are valid field names:
6599
6600     <!-- alphabetical -->
6601     <variablelist>
6602      <varlistentry>
6603       <term><literal>century</literal></term>
6604       <listitem>
6605        <para>
6606         The century
6607        </para>
6608
6609 <screen>
6610 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6611 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6612 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6613 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6614 </screen>
6615
6616        <para>
6617         The first century starts at 0001-01-01 00:00:00 AD, although
6618         they did not know it at the time. This definition applies to all
6619         Gregorian calendar countries. There is no century number 0,
6620         you go from -1 century to 1 century.
6621
6622         If you disagree with this, please write your complaint to:
6623         Pope, Cathedral Saint-Peter of Roma, Vatican.
6624        </para>
6625
6626        <para>
6627         <productname>PostgreSQL</productname> releases before 8.0 did not
6628         follow the conventional numbering of centuries, but just returned
6629         the year field divided by 100.
6630        </para>
6631       </listitem>
6632      </varlistentry>
6633
6634      <varlistentry>
6635       <term><literal>day</literal></term>
6636       <listitem>
6637        <para>
6638         For <type>timestamp</type> values, the day (of the month) field
6639         (1 - 31) ; for <type>interval</type> values, the number of days
6640        </para>
6641
6642 <screen>
6643 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6644 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6645
6646 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
6647 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6648 </screen>
6649
6650
6651
6652       </listitem>
6653      </varlistentry>
6654
6655      <varlistentry>
6656       <term><literal>decade</literal></term>
6657       <listitem>
6658        <para>
6659         The year field divided by 10
6660        </para>
6661
6662 <screen>
6663 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6664 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6665 </screen>
6666       </listitem>
6667      </varlistentry>
6668
6669      <varlistentry>
6670       <term><literal>dow</literal></term>
6671       <listitem>
6672        <para>
6673         The day of the week as Sunday(<literal>0</>) to
6674         Saturday(<literal>6</>)
6675        </para>
6676
6677 <screen>
6678 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6679 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6680 </screen>
6681        <para>
6682         Note that <function>extract</function>'s day of the week numbering
6683         differs from that of the <function>to_char(...,
6684         'D')</function> function.
6685        </para>
6686
6687       </listitem>
6688      </varlistentry>
6689
6690      <varlistentry>
6691       <term><literal>doy</literal></term>
6692       <listitem>
6693        <para>
6694         The day of the year (1 - 365/366)
6695        </para>
6696
6697 <screen>
6698 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6699 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6700 </screen>
6701       </listitem>
6702      </varlistentry>
6703
6704      <varlistentry>
6705       <term><literal>epoch</literal></term>
6706       <listitem>
6707        <para>
6708         For <type>timestamp with time zone</type> values, the
6709         number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
6710         for <type>date</type> and <type>timestamp</type> values, the
6711         number of seconds since 1970-01-01 00:00:00 local time;
6712         for <type>interval</type> values, the total number
6713         of seconds in the interval
6714        </para>
6715
6716 <screen>
6717 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
6718 <lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput>
6719
6720 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6721 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6722 </screen>
6723
6724        <para>
6725         Here is how you can convert an epoch value back to a time
6726         stamp:
6727        </para>
6728 <screen>
6729 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second';
6730 </screen>
6731        <para>
6732         (The <function>to_timestamp</> function encapsulates the above
6733         conversion.)
6734        </para>
6735       </listitem>
6736      </varlistentry>
6737
6738      <varlistentry>
6739       <term><literal>hour</literal></term>
6740       <listitem>
6741        <para>
6742         The hour field (0 - 23)
6743        </para>
6744
6745 <screen>
6746 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6747 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6748 </screen>
6749       </listitem>
6750      </varlistentry>
6751
6752      <varlistentry>
6753       <term><literal>isodow</literal></term>
6754       <listitem>
6755        <para>
6756         The day of the week as Monday(<literal>1</>) to
6757         Sunday(<literal>7</>)
6758        </para>
6759
6760 <screen>
6761 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6762 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6763 </screen>
6764        <para>
6765         This is identical to <literal>dow</> except for Sunday.  This
6766         matches the <acronym>ISO</> 8601 day of the week numbering.
6767        </para>
6768
6769       </listitem>
6770      </varlistentry>
6771
6772      <varlistentry>
6773       <term><literal>isoyear</literal></term>
6774       <listitem>
6775        <para>
6776         The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals)
6777        </para>
6778
6779 <screen>
6780 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6781 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6782 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6783 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6784 </screen>
6785
6786        <para>
6787         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.
6788        </para>
6789        <para>
6790         This field is not available in PostgreSQL releases prior to 8.3.
6791        </para>
6792       </listitem>
6793      </varlistentry>
6794
6795      <varlistentry>
6796       <term><literal>microseconds</literal></term>
6797       <listitem>
6798        <para>
6799         The seconds field, including fractional parts, multiplied by 1
6800         000 000;  note that this includes full seconds
6801        </para>
6802
6803 <screen>
6804 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6805 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6806 </screen>
6807       </listitem>
6808      </varlistentry>
6809
6810      <varlistentry>
6811       <term><literal>millennium</literal></term>
6812       <listitem>
6813        <para>
6814         The millennium
6815        </para>
6816
6817 <screen>
6818 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6819 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6820 </screen>
6821
6822        <para>
6823         Years in the 1900s are in the second millennium.
6824         The third millennium started January 1, 2001.
6825        </para>
6826
6827        <para>
6828         <productname>PostgreSQL</productname> releases before 8.0 did not
6829         follow the conventional numbering of millennia, but just returned
6830         the year field divided by 1000.
6831        </para>
6832       </listitem>
6833      </varlistentry>
6834
6835      <varlistentry>
6836       <term><literal>milliseconds</literal></term>
6837       <listitem>
6838        <para>
6839         The seconds field, including fractional parts, multiplied by
6840         1000.  Note that this includes full seconds.
6841        </para>
6842
6843 <screen>
6844 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6845 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6846 </screen>
6847       </listitem>
6848      </varlistentry>
6849
6850      <varlistentry>
6851       <term><literal>minute</literal></term>
6852       <listitem>
6853        <para>
6854         The minutes field (0 - 59)
6855        </para>
6856
6857 <screen>
6858 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6859 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6860 </screen>
6861       </listitem>
6862      </varlistentry>
6863
6864      <varlistentry>
6865       <term><literal>month</literal></term>
6866       <listitem>
6867        <para>
6868         For <type>timestamp</type> values, the number of the month
6869         within the year (1 - 12) ; for <type>interval</type> values,
6870         the number of months, modulo 12 (0 - 11)
6871        </para>
6872
6873 <screen>
6874 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6875 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6876
6877 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6878 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6879
6880 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6881 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6882 </screen>
6883       </listitem>
6884      </varlistentry>
6885
6886      <varlistentry>
6887       <term><literal>quarter</literal></term>
6888       <listitem>
6889        <para>
6890         The quarter of the year (1 - 4) that the date is in
6891        </para>
6892
6893 <screen>
6894 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6895 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6896 </screen>
6897       </listitem>
6898      </varlistentry>
6899
6900      <varlistentry>
6901       <term><literal>second</literal></term>
6902       <listitem>
6903        <para>
6904         The seconds field, including fractional parts (0 -
6905         59<footnote><simpara>60 if leap seconds are
6906         implemented by the operating system</simpara></footnote>)
6907        </para>
6908
6909 <screen>
6910 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6911 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6912
6913 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6914 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6915 </screen>
6916       </listitem>
6917      </varlistentry>
6918      <varlistentry>
6919       <term><literal>timezone</literal></term>
6920       <listitem>
6921        <para>
6922         The time zone offset from UTC, measured in seconds.  Positive values
6923         correspond to time zones east of UTC, negative values to
6924         zones west of UTC.  (Technically,
6925         <productname>PostgreSQL</productname> uses <acronym>UT1</> because
6926         leap seconds are not handled.)
6927        </para>
6928       </listitem>
6929      </varlistentry>
6930
6931      <varlistentry>
6932       <term><literal>timezone_hour</literal></term>
6933       <listitem>
6934        <para>
6935         The hour component of the time zone offset
6936        </para>
6937       </listitem>
6938      </varlistentry>
6939
6940      <varlistentry>
6941       <term><literal>timezone_minute</literal></term>
6942       <listitem>
6943        <para>
6944         The minute component of the time zone offset
6945        </para>
6946       </listitem>
6947      </varlistentry>
6948
6949      <varlistentry>
6950       <term><literal>week</literal></term>
6951       <listitem>
6952        <para>
6953         The number of the week of the year that the day is in.  By definition
6954         (<acronym>ISO</acronym> 8601), the first week of a year
6955         contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
6956         week starts on Monday.)  In other words, the first Thursday of
6957         a year is in week 1 of that year.
6958        </para>
6959        <para>
6960         Because of this, it is possible for early January dates to be part of the
6961         52nd or 53rd week of the previous year.  For example, <literal>2005-01-01</>
6962         is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of
6963         the 52nd week of year 2005.
6964        </para>
6965
6966 <screen>
6967 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6968 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6969 </screen>
6970       </listitem>
6971      </varlistentry>
6972
6973      <varlistentry>
6974       <term><literal>year</literal></term>
6975       <listitem>
6976        <para>
6977         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting
6978         <literal>BC</> years from <literal>AD</> years should be done with care.
6979        </para>
6980
6981 <screen>
6982 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6983 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6984 </screen>
6985       </listitem>
6986      </varlistentry>
6987
6988     </variablelist>
6989    </para>
6990
6991    <para>
6992     The <function>extract</function> function is primarily intended
6993     for computational processing.  For formatting date/time values for
6994     display, see <xref linkend="functions-formatting">.
6995    </para>
6996
6997    <para>
6998     The <function>date_part</function> function is modeled on the traditional
6999     <productname>Ingres</productname> equivalent to the
7000     <acronym>SQL</acronym>-standard function <function>extract</function>:
7001 <synopsis>
7002 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
7003 </synopsis>
7004     Note that here the <replaceable>field</replaceable> parameter needs to
7005     be a string value, not a name.  The valid field names for
7006     <function>date_part</function> are the same as for
7007     <function>extract</function>.
7008    </para>
7009
7010 <screen>
7011 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
7012 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
7013
7014 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
7015 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
7016 </screen>
7017
7018   </sect2>
7019
7020   <sect2 id="functions-datetime-trunc">
7021    <title><function>date_trunc</function></title>
7022
7023    <indexterm>
7024     <primary>date_trunc</primary>
7025    </indexterm>
7026
7027    <para>
7028     The function <function>date_trunc</function> is conceptually
7029     similar to the <function>trunc</function> function for numbers.
7030    </para>
7031
7032    <para>
7033 <synopsis>
7034 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
7035 </synopsis>
7036     <replaceable>source</replaceable> is a value expression of type
7037     <type>timestamp</type> or <type>interval</>.
7038     (Values of type <type>date</type> and
7039     <type>time</type> are cast automatically to <type>timestamp</type> or
7040     <type>interval</>, respectively.)
7041     <replaceable>field</replaceable> selects to which precision to
7042     truncate the input value.  The return value is of type
7043     <type>timestamp</type> or <type>interval</>
7044     with all fields that are less significant than the
7045     selected one set to zero (or one, for day and month).
7046    </para>
7047
7048    <para>
7049     Valid values for <replaceable>field</replaceable> are:
7050     <simplelist>
7051      <member><literal>microseconds</literal></member>
7052      <member><literal>milliseconds</literal></member>
7053      <member><literal>second</literal></member>
7054      <member><literal>minute</literal></member>
7055      <member><literal>hour</literal></member>
7056      <member><literal>day</literal></member>
7057      <member><literal>week</literal></member>
7058      <member><literal>month</literal></member>
7059      <member><literal>quarter</literal></member>
7060      <member><literal>year</literal></member>
7061      <member><literal>decade</literal></member>
7062      <member><literal>century</literal></member>
7063      <member><literal>millennium</literal></member>
7064     </simplelist>
7065    </para>
7066
7067    <para>
7068     Examples:
7069 <screen>
7070 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
7071 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
7072
7073 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
7074 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
7075 </screen>
7076    </para>
7077   </sect2>
7078
7079   <sect2 id="functions-datetime-zoneconvert">
7080    <title><literal>AT TIME ZONE</literal></title>
7081
7082    <indexterm>
7083     <primary>time zone</primary>
7084     <secondary>conversion</secondary>
7085    </indexterm>
7086
7087    <indexterm>
7088     <primary>AT TIME ZONE</primary>
7089    </indexterm>
7090
7091    <para>
7092     The <literal>AT TIME ZONE</literal> construct allows conversions
7093     of time stamps to different time zones.  <xref
7094     linkend="functions-datetime-zoneconvert-table"> shows its
7095     variants.
7096    </para>
7097
7098     <table id="functions-datetime-zoneconvert-table">
7099      <title><literal>AT TIME ZONE</literal> Variants</title>
7100      <tgroup cols="3">
7101       <thead>
7102        <row>
7103         <entry>Expression</entry>
7104         <entry>Return Type</entry>
7105         <entry>Description</entry>
7106        </row>
7107       </thead>
7108
7109       <tbody>
7110        <row>
7111         <entry>
7112          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7113         </entry>
7114         <entry><type>timestamp with time zone</type></entry>
7115         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
7116        </row>
7117
7118        <row>
7119         <entry>
7120          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7121         </entry>
7122         <entry><type>timestamp without time zone</type></entry>
7123         <entry>Convert given time stamp <emphasis>with time zone</> to the new time
7124         zone, with no time zone designation</entry>
7125        </row>
7126
7127        <row>
7128         <entry>
7129          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7130         </entry>
7131         <entry><type>time with time zone</type></entry>
7132         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
7133        </row>
7134       </tbody>
7135      </tgroup>
7136     </table>
7137
7138    <para>
7139     In these expressions, the desired time zone <replaceable>zone</> can be
7140     specified either as a text string (e.g., <literal>'PST'</literal>)
7141     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
7142     In the text case, a time zone name can be specified in any of the ways
7143     described in <xref linkend="datatype-timezones">.
7144    </para>
7145
7146    <para>
7147     Examples (assuming the local time zone is <literal>PST8PDT</>):
7148 <screen>
7149 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
7150 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
7151
7152 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
7153 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
7154 </screen>
7155     The first example takes a time stamp without time zone and interprets it as MST time
7156     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes
7157     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
7158    </para>
7159
7160    <para>
7161     The function <literal><function>timezone</function>(<replaceable>zone</>,
7162     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
7163     <literal><replaceable>timestamp</> AT TIME ZONE
7164     <replaceable>zone</></literal>.
7165    </para>
7166   </sect2>
7167
7168   <sect2 id="functions-datetime-current">
7169    <title>Current Date/Time</title>
7170
7171    <indexterm>
7172     <primary>date</primary>
7173     <secondary>current</secondary>
7174    </indexterm>
7175
7176    <indexterm>
7177     <primary>time</primary>
7178     <secondary>current</secondary>
7179    </indexterm>
7180
7181    <para>
7182     <productname>PostgreSQL</productname> provides a number of functions
7183     that return values related to the current date and time.  These
7184     SQL-standard functions all return values based on the start time of
7185     the current transaction:
7186 <synopsis>
7187 CURRENT_DATE
7188 CURRENT_TIME
7189 CURRENT_TIMESTAMP
7190 CURRENT_TIME(<replaceable>precision</replaceable>)
7191 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
7192 LOCALTIME
7193 LOCALTIMESTAMP
7194 LOCALTIME(<replaceable>precision</replaceable>)
7195 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
7196 </synopsis>
7197     </para>
7198
7199     <para>
7200      <function>CURRENT_TIME</function> and
7201      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
7202      <function>LOCALTIME</function> and
7203      <function>LOCALTIMESTAMP</function> deliver values without time zone.
7204     </para>
7205
7206     <para>
7207      <function>CURRENT_TIME</function>,
7208      <function>CURRENT_TIMESTAMP</function>,
7209      <function>LOCALTIME</function>, and
7210      <function>LOCALTIMESTAMP</function>
7211      can optionally take
7212      a precision parameter, which causes the result to be rounded
7213      to that many fractional digits in the seconds field.  Without a precision parameter,
7214      the result is given to the full available precision.
7215     </para>
7216
7217    <para>
7218     Some examples:
7219 <screen>
7220 SELECT CURRENT_TIME;
7221 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
7222
7223 SELECT CURRENT_DATE;
7224 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
7225
7226 SELECT CURRENT_TIMESTAMP;
7227 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
7228
7229 SELECT CURRENT_TIMESTAMP(2);
7230 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
7231
7232 SELECT LOCALTIMESTAMP;
7233 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
7234 </screen>
7235    </para>
7236
7237    <para>
7238     Since these functions return
7239     the start time of the current transaction, their values do not
7240     change during the transaction. This is considered a feature:
7241     the intent is to allow a single transaction to have a consistent
7242     notion of the <quote>current</quote> time, so that multiple
7243     modifications within the same transaction bear the same
7244     time stamp.
7245    </para>
7246
7247    <note>
7248     <para>
7249      Other database systems might advance these values more
7250      frequently.
7251     </para>
7252    </note>
7253
7254    <para>
7255     <productname>PostgreSQL</productname> also provides functions that
7256     return the start time of the current statement, as well as the actual
7257     current time at the instant the function is called.  The complete list
7258     of non-SQL-standard time functions is:
7259 <synopsis>
7260 transaction_timestamp()
7261 statement_timestamp()
7262 clock_timestamp()
7263 timeofday()
7264 now()
7265 </synopsis>
7266    </para>
7267
7268    <para>
7269     <function>transaction_timestamp()</> is equivalent to
7270     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
7271     what it returns.
7272     <function>statement_timestamp()</> returns the start time of the current
7273     statement (more specifically, the time of receipt of the latest command
7274     message from the client).
7275     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
7276     return the same value during the first command of a transaction, but might
7277     differ during subsequent commands.
7278     <function>clock_timestamp()</> returns the actual current time, and
7279     therefore its value changes even within a single SQL command.
7280     <function>timeofday()</> is a historical
7281     <productname>PostgreSQL</productname> function.  Like
7282     <function>clock_timestamp()</>, it returns the actual current time,
7283     but as a formatted <type>text</> string rather than a <type>timestamp
7284     with time zone</> value.
7285     <function>now()</> is a traditional <productname>PostgreSQL</productname>
7286     equivalent to <function>transaction_timestamp()</function>.
7287    </para>
7288
7289    <para>
7290     All the date/time data types also accept the special literal value
7291     <literal>now</literal> to specify the current date and time (again,
7292     interpreted as the transaction start time).  Thus,
7293     the following three all return the same result:
7294 <programlisting>
7295 SELECT CURRENT_TIMESTAMP;
7296 SELECT now();
7297 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
7298 </programlisting>
7299    </para>
7300
7301     <tip>
7302      <para>
7303       You do not want to use the third form when specifying a <literal>DEFAULT</>
7304       clause while creating a table.  The system will convert <literal>now</literal>
7305       to a <type>timestamp</type> as soon as the constant is parsed, so that when
7306       the default value is needed,
7307       the time of the table creation would be used!  The first two
7308       forms will not be evaluated until the default value is used,
7309       because they are function calls.  Thus they will give the desired
7310       behavior of defaulting to the time of row insertion.
7311      </para>
7312     </tip>
7313   </sect2>
7314
7315   <sect2 id="functions-datetime-delay">
7316    <title>Delaying Execution</title>
7317
7318    <indexterm>
7319     <primary>pg_sleep</primary>
7320    </indexterm>
7321    <indexterm>
7322     <primary>sleep</primary>
7323    </indexterm>
7324    <indexterm>
7325     <primary>delay</primary>
7326    </indexterm>
7327
7328    <para>
7329     The following function is available to delay execution of the server
7330     process:
7331 <synopsis>
7332 pg_sleep(<replaceable>seconds</replaceable>)
7333 </synopsis>
7334
7335     <function>pg_sleep</function> makes the current session's process
7336     sleep until <replaceable>seconds</replaceable> seconds have
7337     elapsed.  <replaceable>seconds</replaceable> is a value of type
7338     <type>double precision</>, so fractional-second delays can be specified.
7339     For example:
7340
7341 <programlisting>
7342 SELECT pg_sleep(1.5);
7343 </programlisting>
7344    </para>
7345
7346    <note>
7347      <para>
7348       The effective resolution of the sleep interval is platform-specific;
7349       0.01 seconds is a common value.  The sleep delay will be at least as long
7350       as specified. It might be longer depending on factors such as server load.
7351      </para>
7352    </note>
7353
7354    <warning>
7355      <para>
7356       Make sure that your session does not hold more locks than necessary
7357       when calling <function>pg_sleep</function>.  Otherwise other sessions
7358       might have to wait for your sleeping process, slowing down the entire
7359       system.
7360      </para>
7361    </warning>
7362   </sect2>
7363
7364  </sect1>
7365
7366
7367  <sect1 id="functions-enum">
7368   <title>Enum Support Functions</title>
7369
7370   <para>
7371    For enum types (described in <xref linkend="datatype-enum">),
7372    there are several functions that allow cleaner programming without
7373    hard-coding particular values of an enum type.
7374    These are listed in <xref linkend="functions-enum-table">. The examples
7375    assume an enum type created as:
7376
7377 <programlisting>
7378 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
7379 </programlisting>
7380
7381   </para>
7382
7383   <table id="functions-enum-table">
7384     <title>Enum Support Functions</title>
7385     <tgroup cols="4">
7386      <thead>
7387       <row>
7388        <entry>Function</entry>
7389        <entry>Description</entry>
7390        <entry>Example</entry>
7391        <entry>Example Result</entry>
7392       </row>
7393      </thead>
7394      <tbody>
7395       <row>
7396        <entry>
7397          <indexterm>
7398           <primary>enum_first</primary>
7399          </indexterm>
7400          <literal>enum_first(anyenum)</literal>
7401        </entry>
7402        <entry>Returns the first value of the input enum type</entry>
7403        <entry><literal>enum_first(null::rainbow)</literal></entry>
7404        <entry><literal>red</literal></entry>
7405       </row>
7406       <row>
7407        <entry>
7408          <indexterm>
7409           <primary>enum_last</primary>
7410          </indexterm>
7411          <literal>enum_last(anyenum)</literal>
7412        </entry>
7413        <entry>Returns the last value of the input enum type</entry>
7414        <entry><literal>enum_last(null::rainbow)</literal></entry>
7415        <entry><literal>purple</literal></entry>
7416       </row>
7417       <row>
7418        <entry>
7419          <indexterm>
7420           <primary>enum_range</primary>
7421          </indexterm>
7422          <literal>enum_range(anyenum)</literal>
7423        </entry>
7424        <entry>Returns all values of the input enum type in an ordered array</entry>
7425        <entry><literal>enum_range(null::rainbow)</literal></entry>
7426        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
7427       </row>
7428       <row>
7429        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
7430        <entry morerows="2">
7431         Returns the range between the two given enum values, as an ordered
7432         array. The values must be from the same enum type. If the first
7433         parameter is null, the result will start with the first value of
7434         the enum type.
7435         If the second parameter is null, the result will end with the last
7436         value of the enum type.
7437        </entry>
7438        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
7439        <entry><literal>{orange,yellow,green}</literal></entry>
7440       </row>
7441       <row>
7442        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
7443        <entry><literal>{red,orange,yellow,green}</literal></entry>
7444       </row>
7445       <row>
7446        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
7447        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
7448       </row>
7449      </tbody>
7450     </tgroup>
7451    </table>
7452
7453    <para>
7454     Notice that except for the two-argument form of <function>enum_range</>,
7455     these functions disregard the specific value passed to them; they care
7456     only about its declared data type.  Either null or a specific value of
7457     the type can be passed, with the same result.  It is more common to
7458     apply these functions to a table column or function argument than to
7459     a hardwired type name as suggested by the examples.
7460    </para>
7461  </sect1>
7462
7463  <sect1 id="functions-geometry">
7464   <title>Geometric Functions and Operators</title>
7465
7466    <para>
7467     The geometric types <type>point</type>, <type>box</type>,
7468     <type>lseg</type>, <type>line</type>, <type>path</type>,
7469     <type>polygon</type>, and <type>circle</type> have a large set of
7470     native support functions and operators, shown in <xref
7471     linkend="functions-geometry-op-table">, <xref
7472     linkend="functions-geometry-func-table">, and <xref
7473     linkend="functions-geometry-conv-table">.
7474    </para>
7475
7476    <caution>
7477     <para>
7478      Note that the <quote>same as</> operator, <literal>~=</>, represents
7479      the usual notion of equality for the <type>point</type>,
7480      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
7481      Some of these types also have an <literal>=</> operator, but
7482      <literal>=</> compares
7483      for equal <emphasis>areas</> only.  The other scalar comparison operators
7484      (<literal>&lt;=</> and so on) likewise compare areas for these types.
7485     </para>
7486    </caution>
7487
7488    <table id="functions-geometry-op-table">
7489      <title>Geometric Operators</title>
7490      <tgroup cols="3">
7491       <thead>
7492        <row>
7493         <entry>Operator</entry>
7494         <entry>Description</entry>
7495         <entry>Example</entry>
7496        </row>
7497       </thead>
7498       <tbody>
7499        <row>
7500         <entry> <literal>+</literal> </entry>
7501         <entry>Translation</entry>
7502         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
7503        </row>
7504        <row>
7505         <entry> <literal>-</literal> </entry>
7506         <entry>Translation</entry>
7507         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
7508        </row>
7509        <row>
7510         <entry> <literal>*</literal> </entry>
7511         <entry>Scaling/rotation</entry>
7512         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
7513        </row>
7514        <row>
7515         <entry> <literal>/</literal> </entry>
7516         <entry>Scaling/rotation</entry>
7517         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
7518        </row>
7519        <row>
7520         <entry> <literal>#</literal> </entry>
7521         <entry>Point or box of intersection</entry>
7522         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
7523        </row>
7524        <row>
7525         <entry> <literal>#</literal> </entry>
7526         <entry>Number of points in path or polygon</entry>
7527         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
7528        </row>
7529        <row>
7530         <entry> <literal>@-@</literal> </entry>
7531         <entry>Length or circumference</entry>
7532         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
7533        </row>
7534        <row>
7535         <entry> <literal>@@</literal> </entry>
7536         <entry>Center</entry>
7537         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
7538        </row>
7539        <row>
7540         <entry> <literal>##</literal> </entry>
7541         <entry>Closest point to first operand on second operand</entry>
7542         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
7543        </row>
7544        <row>
7545         <entry> <literal>&lt;-&gt;</literal> </entry>
7546         <entry>Distance between</entry>
7547         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
7548        </row>
7549        <row>
7550         <entry> <literal>&amp;&amp;</literal> </entry>
7551         <entry>Overlaps?  (One point in common makes this true.)</entry>
7552         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
7553        </row>
7554        <row>
7555         <entry> <literal>&lt;&lt;</literal> </entry>
7556         <entry>Is strictly left of?</entry>
7557         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
7558        </row>
7559        <row>
7560         <entry> <literal>&gt;&gt;</literal> </entry>
7561         <entry>Is strictly right of?</entry>
7562         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
7563        </row>
7564        <row>
7565         <entry> <literal>&amp;&lt;</literal> </entry>
7566         <entry>Does not extend to the right of?</entry>
7567         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
7568        </row>
7569        <row>
7570         <entry> <literal>&amp;&gt;</literal> </entry>
7571         <entry>Does not extend to the left of?</entry>
7572         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
7573        </row>
7574        <row>
7575         <entry> <literal>&lt;&lt;|</literal> </entry>
7576         <entry>Is strictly below?</entry>
7577         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
7578        </row>
7579        <row>
7580         <entry> <literal>|&gt;&gt;</literal> </entry>
7581         <entry>Is strictly above?</entry>
7582         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
7583        </row>
7584        <row>
7585         <entry> <literal>&amp;&lt;|</literal> </entry>
7586         <entry>Does not extend above?</entry>
7587         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
7588        </row>
7589        <row>
7590         <entry> <literal>|&amp;&gt;</literal> </entry>
7591         <entry>Does not extend below?</entry>
7592         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
7593        </row>
7594        <row>
7595         <entry> <literal>&lt;^</literal> </entry>
7596         <entry>Is below (allows touching)?</entry>
7597         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
7598        </row>
7599        <row>
7600         <entry> <literal>&gt;^</literal> </entry>
7601         <entry>Is above (allows touching)?</entry>
7602         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
7603        </row>
7604        <row>
7605         <entry> <literal>?#</literal> </entry>
7606         <entry>Intersects?</entry>
7607         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7608        </row>
7609        <row>
7610         <entry> <literal>?-</literal> </entry>
7611         <entry>Is horizontal?</entry>
7612         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7613        </row>
7614        <row>
7615         <entry> <literal>?-</literal> </entry>
7616         <entry>Are horizontally aligned?</entry>
7617         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7618        </row>
7619        <row>
7620         <entry> <literal>?|</literal> </entry>
7621         <entry>Is vertical?</entry>
7622         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7623        </row>
7624        <row>
7625         <entry> <literal>?|</literal> </entry>
7626         <entry>Are vertically aligned?</entry>
7627         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7628        </row>
7629        <row>
7630         <entry> <literal>?-|</literal> </entry>
7631         <entry>Is perpendicular?</entry>
7632         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7633        </row>
7634        <row>
7635         <entry> <literal>?||</literal> </entry>
7636         <entry>Are parallel?</entry>
7637         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7638        </row>
7639        <row>
7640         <entry> <literal>@&gt;</literal> </entry>
7641         <entry>Contains?</entry>
7642         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7643        </row>
7644        <row>
7645         <entry> <literal>&lt;@</literal> </entry>
7646         <entry>Contained in or on?</entry>
7647         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7648        </row>
7649        <row>
7650         <entry> <literal>~=</literal> </entry>
7651         <entry>Same as?</entry>
7652         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7653        </row>
7654       </tbody>
7655      </tgroup>
7656    </table>
7657
7658    <note>
7659     <para>
7660      Before <productname>PostgreSQL</productname> 8.2, the containment
7661      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7662      called <literal>~</> and <literal>@</>.  These names are still
7663      available, but are deprecated and will eventually be removed.
7664     </para>
7665    </note>
7666
7667    <indexterm>
7668     <primary>area</primary>
7669    </indexterm>
7670    <indexterm>
7671     <primary>center</primary>
7672    </indexterm>
7673    <indexterm>
7674     <primary>diameter</primary>
7675    </indexterm>
7676    <indexterm>
7677     <primary>height</primary>
7678    </indexterm>
7679    <indexterm>
7680     <primary>isclosed</primary>
7681    </indexterm>
7682    <indexterm>
7683     <primary>isopen</primary>
7684    </indexterm>
7685    <indexterm>
7686     <primary>length</primary>
7687    </indexterm>
7688    <indexterm>
7689     <primary>npoints</primary>
7690    </indexterm>
7691    <indexterm>
7692     <primary>pclose</primary>
7693    </indexterm>
7694    <indexterm>
7695     <primary>popen</primary>
7696    </indexterm>
7697    <indexterm>
7698     <primary>radius</primary>
7699    </indexterm>
7700    <indexterm>
7701     <primary>width</primary>
7702    </indexterm>
7703
7704    <table id="functions-geometry-func-table">
7705      <title>Geometric Functions</title>
7706      <tgroup cols="4">
7707       <thead>
7708        <row>
7709         <entry>Function</entry>
7710         <entry>Return Type</entry>
7711         <entry>Description</entry>
7712         <entry>Example</entry>
7713        </row>
7714       </thead>
7715       <tbody>
7716        <row>
7717         <entry><literal><function>area(<replaceable>object</>)</function></literal></entry>
7718         <entry><type>double precision</type></entry>
7719         <entry>area</entry>
7720         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7721        </row>
7722        <row>
7723         <entry><literal><function>center(<replaceable>object</>)</function></literal></entry>
7724         <entry><type>point</type></entry>
7725         <entry>center</entry>
7726         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7727        </row>
7728        <row>
7729         <entry><literal><function>diameter(<type>circle</>)</function></literal></entry>
7730         <entry><type>double precision</type></entry>
7731         <entry>diameter of circle</entry>
7732         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7733        </row>
7734        <row>
7735         <entry><literal><function>height(<type>box</>)</function></literal></entry>
7736         <entry><type>double precision</type></entry>
7737         <entry>vertical size of box</entry>
7738         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7739        </row>
7740        <row>
7741         <entry><literal><function>isclosed(<type>path</>)</function></literal></entry>
7742         <entry><type>boolean</type></entry>
7743         <entry>a closed path?</entry>
7744         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7745        </row>
7746        <row>
7747         <entry><literal><function>isopen(<type>path</>)</function></literal></entry>
7748         <entry><type>boolean</type></entry>
7749         <entry>an open path?</entry>
7750         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7751        </row>
7752        <row>
7753         <entry><literal><function>length(<replaceable>object</>)</function></literal></entry>
7754         <entry><type>double precision</type></entry>
7755         <entry>length</entry>
7756         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7757        </row>
7758        <row>
7759         <entry><literal><function>npoints(<type>path</>)</function></literal></entry>
7760         <entry><type>int</type></entry>
7761         <entry>number of points</entry>
7762         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7763        </row>
7764        <row>
7765         <entry><literal><function>npoints(<type>polygon</>)</function></literal></entry>
7766         <entry><type>int</type></entry>
7767         <entry>number of points</entry>
7768         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7769        </row>
7770        <row>
7771         <entry><literal><function>pclose(<type>path</>)</function></literal></entry>
7772         <entry><type>path</type></entry>
7773         <entry>convert path to closed</entry>
7774         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7775        </row>
7776 <![IGNORE[
7777 <!-- Not defined by this name. Implements the intersection operator '#' -->
7778        <row>
7779         <entry><literal><function>point(<type>lseg</>, <type>lseg</>)</function></literal></entry>
7780         <entry><type>point</type></entry>
7781         <entry>intersection</entry>
7782         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7783        </row>
7784 ]]>
7785        <row>
7786         <entry><literal><function>popen(<type>path</>)</function></literal></entry>
7787         <entry><type>path</type></entry>
7788         <entry>convert path to open</entry>
7789         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7790        </row>
7791        <row>
7792         <entry><literal><function>radius(<type>circle</type>)</function></literal></entry>
7793         <entry><type>double precision</type></entry>
7794         <entry>radius of circle</entry>
7795         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7796        </row>
7797        <row>
7798         <entry><literal><function>width(<type>box</>)</function></literal></entry>
7799         <entry><type>double precision</type></entry>
7800         <entry>horizontal size of box</entry>
7801         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7802        </row>
7803       </tbody>
7804      </tgroup>
7805    </table>
7806
7807    <table id="functions-geometry-conv-table">
7808      <title>Geometric Type Conversion Functions</title>
7809      <tgroup cols="4">
7810       <thead>
7811        <row>
7812         <entry>Function</entry>
7813         <entry>Return Type</entry>
7814         <entry>Description</entry>
7815         <entry>Example</entry>
7816        </row>
7817       </thead>
7818       <tbody>
7819        <row>
7820         <entry>
7821          <indexterm>
7822           <primary>box</primary>
7823          </indexterm>
7824          <literal><function>box(<type>circle</type>)</function></literal>
7825         </entry>
7826         <entry><type>box</type></entry>
7827         <entry>circle to box</entry>
7828         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7829        </row>
7830        <row>
7831         <entry><literal><function>box(<type>point</type>, <type>point</type>)</function></literal></entry>
7832         <entry><type>box</type></entry>
7833         <entry>points to box</entry>
7834         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7835        </row>
7836        <row>
7837         <entry><literal><function>box(<type>polygon</type>)</function></literal></entry>
7838         <entry><type>box</type></entry>
7839         <entry>polygon to box</entry>
7840         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7841        </row>
7842        <row>
7843         <entry>
7844          <indexterm>
7845           <primary>circle</primary>
7846          </indexterm>
7847          <literal><function>circle(<type>box</type>)</function></literal>
7848         </entry>
7849         <entry><type>circle</type></entry>
7850         <entry>box to circle</entry>
7851         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7852        </row>
7853        <row>
7854         <entry><literal><function>circle(<type>point</type>, <type>double precision</type>)</function></literal></entry>
7855         <entry><type>circle</type></entry>
7856         <entry>center and radius to circle</entry>
7857         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7858        </row>
7859        <row>
7860         <entry><literal><function>circle(<type>polygon</type>)</function></literal></entry>
7861         <entry><type>circle</type></entry>
7862         <entry>polygon to circle</entry>
7863         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7864        </row>
7865        <row>
7866         <entry>
7867          <indexterm>
7868           <primary>lseg</primary>
7869          </indexterm>
7870          <literal><function>lseg(<type>box</type>)</function></literal>
7871         </entry>
7872         <entry><type>lseg</type></entry>
7873         <entry>box diagonal to line segment</entry>
7874         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7875        </row>
7876        <row>
7877         <entry><literal><function>lseg(<type>point</type>, <type>point</type>)</function></literal></entry>
7878         <entry><type>lseg</type></entry>
7879         <entry>points to line segment</entry>
7880         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7881        </row>
7882        <row>
7883         <entry>
7884          <indexterm>
7885           <primary>path</primary>
7886          </indexterm>
7887          <literal><function>path(<type>polygon</type>)</function></literal>
7888         </entry>
7889         <entry><type>path</type></entry>
7890         <entry>polygon to path</entry>
7891         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7892        </row>
7893        <row>
7894         <entry>
7895          <indexterm>
7896           <primary>point</primary>
7897          </indexterm>
7898          <literal><function>point</function>(<type>double
7899          precision</type>, <type>double precision</type>)</literal>
7900         </entry>
7901         <entry><type>point</type></entry>
7902         <entry>construct point</entry>
7903         <entry><literal>point(23.4, -44.5)</literal></entry>
7904        </row>
7905        <row>
7906         <entry><literal><function>point(<type>box</type>)</function></literal></entry>
7907         <entry><type>point</type></entry>
7908         <entry>center of box</entry>
7909         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7910        </row>
7911        <row>
7912         <entry><literal><function>point(<type>circle</type>)</function></literal></entry>
7913         <entry><type>point</type></entry>
7914         <entry>center of circle</entry>
7915         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7916        </row>
7917        <row>
7918         <entry><literal><function>point(<type>lseg</type>)</function></literal></entry>
7919         <entry><type>point</type></entry>
7920         <entry>center of line segment</entry>
7921         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7922        </row>
7923        <row>
7924         <entry><literal><function>point(<type>polygon</type>)</function></literal></entry>
7925         <entry><type>point</type></entry>
7926         <entry>center of polygon</entry>
7927         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7928        </row>
7929        <row>
7930         <entry>
7931          <indexterm>
7932           <primary>polygon</primary>
7933          </indexterm>
7934          <literal><function>polygon(<type>box</type>)</function></literal>
7935         </entry>
7936         <entry><type>polygon</type></entry>
7937         <entry>box to 4-point polygon</entry>
7938         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7939        </row>
7940        <row>
7941         <entry><literal><function>polygon(<type>circle</type>)</function></literal></entry>
7942         <entry><type>polygon</type></entry>
7943         <entry>circle to 12-point polygon</entry>
7944         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7945        </row>
7946        <row>
7947         <entry><literal><function>polygon(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</function></literal></entry>
7948         <entry><type>polygon</type></entry>
7949         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
7950         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7951        </row>
7952        <row>
7953         <entry><literal><function>polygon(<type>path</type>)</function></literal></entry>
7954         <entry><type>polygon</type></entry>
7955         <entry>path to polygon</entry>
7956         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7957        </row>
7958       </tbody>
7959      </tgroup>
7960    </table>
7961
7962     <para>
7963      It is possible to access the two component numbers of a <type>point</>
7964      as though the point were an array with indexes 0 and 1.  For example, if
7965      <literal>t.p</> is a <type>point</> column then
7966      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7967      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7968      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7969      as an array of two <type>point</> values.
7970     </para>
7971
7972     <para>
7973      The <function>area</function> function works for the types
7974      <type>box</type>, <type>circle</type>, and <type>path</type>.
7975      The <function>area</function> function only works on the
7976      <type>path</type> data type if the points in the
7977      <type>path</type> are non-intersecting.  For example, the
7978      <type>path</type>
7979      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7980      will not work;  however, the following visually identical
7981      <type>path</type>
7982      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7983      will work.  If the concept of an intersecting versus
7984      non-intersecting <type>path</type> is confusing, draw both of the
7985      above <type>path</type>s side by side on a piece of graph paper.
7986     </para>
7987
7988   </sect1>
7989
7990
7991  <sect1 id="functions-net">
7992   <title>Network Address Functions and Operators</title>
7993
7994   <para>
7995    <xref linkend="cidr-inet-operators-table"> shows the operators
7996    available for the <type>cidr</type> and <type>inet</type> types.
7997    The operators <literal>&lt;&lt;</literal>,
7998    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
7999    <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
8000    consider only the network parts of the two addresses (ignoring any
8001    host part) and determine whether one network is identical to
8002    or a subnet of the other.
8003   </para>
8004
8005     <table id="cidr-inet-operators-table">
8006      <title><type>cidr</type> and <type>inet</type> Operators</title>
8007      <tgroup cols="3">
8008       <thead>
8009        <row>
8010         <entry>Operator</entry>
8011         <entry>Description</entry>
8012         <entry>Example</entry>
8013        </row>
8014       </thead>
8015       <tbody>
8016        <row>
8017         <entry> <literal>&lt;</literal> </entry>
8018         <entry>is less than</entry>
8019         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
8020        </row>
8021        <row>
8022         <entry> <literal>&lt;=</literal> </entry>
8023         <entry>is less than or equal</entry>
8024         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
8025        </row>
8026        <row>
8027         <entry> <literal>=</literal> </entry>
8028         <entry>equals</entry>
8029         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
8030        </row>
8031        <row>
8032         <entry> <literal>&gt;=</literal> </entry>
8033         <entry>is greater or equal</entry>
8034         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
8035        </row>
8036        <row>
8037         <entry> <literal>&gt;</literal> </entry>
8038         <entry>is greater than</entry>
8039         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
8040        </row>
8041        <row>
8042         <entry> <literal>&lt;&gt;</literal> </entry>
8043         <entry>is not equal</entry>
8044         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
8045        </row>
8046        <row>
8047         <entry> <literal>&lt;&lt;</literal> </entry>
8048         <entry>is contained within</entry>
8049         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
8050        </row>
8051        <row>
8052         <entry> <literal>&lt;&lt;=</literal> </entry>
8053         <entry>is contained within or equals</entry>
8054         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
8055        </row>
8056        <row>
8057         <entry> <literal>&gt;&gt;</literal> </entry>
8058         <entry>contains</entry>
8059         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
8060        </row>
8061        <row>
8062         <entry> <literal>&gt;&gt;=</literal> </entry>
8063         <entry>contains or equals</entry>
8064         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
8065        </row>
8066        <row>
8067         <entry> <literal>~</literal> </entry>
8068         <entry>bitwise NOT</entry>
8069         <entry><literal>~ inet '192.168.1.6'</literal></entry>
8070        </row>
8071        <row>
8072         <entry> <literal>&amp;</literal> </entry>
8073         <entry>bitwise AND</entry>
8074         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
8075        </row>
8076        <row>
8077         <entry> <literal>|</literal> </entry>
8078         <entry>bitwise OR</entry>
8079         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
8080        </row>
8081        <row>
8082         <entry> <literal>+</literal> </entry>
8083         <entry>addition</entry>
8084         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
8085        </row>
8086        <row>
8087         <entry> <literal>-</literal> </entry>
8088         <entry>subtraction</entry>
8089         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
8090        </row>
8091        <row>
8092         <entry> <literal>-</literal> </entry>
8093         <entry>subtraction</entry>
8094         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
8095        </row>
8096       </tbody>
8097      </tgroup>
8098     </table>
8099
8100   <para>
8101    <xref linkend="cidr-inet-functions-table"> shows the functions
8102    available for use with the <type>cidr</type> and <type>inet</type>
8103    types.  The <function>abbrev</function>, <function>host</function>,
8104    and <function>text</function>
8105    functions are primarily intended to offer alternative display
8106    formats.
8107   </para>
8108
8109     <table id="cidr-inet-functions-table">
8110      <title><type>cidr</type> and <type>inet</type> Functions</title>
8111      <tgroup cols="5">
8112       <thead>
8113        <row>
8114         <entry>Function</entry>
8115         <entry>Return Type</entry>
8116         <entry>Description</entry>
8117         <entry>Example</entry>
8118         <entry>Result</entry>
8119        </row>
8120       </thead>
8121       <tbody>
8122        <row>
8123         <entry>
8124          <indexterm>
8125           <primary>abbrev</primary>
8126          </indexterm>
8127          <literal><function>abbrev(<type>inet</type>)</function></literal>
8128         </entry>
8129         <entry><type>text</type></entry>
8130         <entry>abbreviated display format as text</entry>
8131         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
8132         <entry><literal>10.1.0.0/16</literal></entry>
8133        </row>
8134        <row>
8135         <entry><literal><function>abbrev(<type>cidr</type>)</function></literal></entry>
8136         <entry><type>text</type></entry>
8137         <entry>abbreviated display format as text</entry>
8138         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
8139         <entry><literal>10.1/16</literal></entry>
8140        </row>
8141        <row>
8142         <entry>
8143          <indexterm>
8144           <primary>broadcast</primary>
8145          </indexterm>
8146          <literal><function>broadcast(<type>inet</type>)</function></literal>
8147         </entry>
8148         <entry><type>inet</type></entry>
8149         <entry>broadcast address for network</entry>
8150         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
8151         <entry><literal>192.168.1.255/24</literal></entry>
8152        </row>
8153        <row>
8154         <entry>
8155          <indexterm>
8156           <primary>family</primary>
8157          </indexterm>
8158          <literal><function>family(<type>inet</type>)</function></literal>
8159         </entry>
8160         <entry><type>int</type></entry>
8161         <entry>extract family of address; <literal>4</literal> for IPv4,
8162          <literal>6</literal> for IPv6</entry>
8163         <entry><literal>family('::1')</literal></entry>
8164         <entry><literal>6</literal></entry>
8165        </row>
8166        <row>
8167         <entry>
8168          <indexterm>
8169           <primary>host</primary>
8170          </indexterm>
8171          <literal><function>host(<type>inet</type>)</function></literal>
8172         </entry>
8173         <entry><type>text</type></entry>
8174         <entry>extract IP address as text</entry>
8175         <entry><literal>host('192.168.1.5/24')</literal></entry>
8176         <entry><literal>192.168.1.5</literal></entry>
8177        </row>
8178        <row>
8179         <entry>
8180          <indexterm>
8181           <primary>hostmask</primary>
8182          </indexterm>
8183          <literal><function>hostmask(<type>inet</type>)</function></literal>
8184         </entry>
8185         <entry><type>inet</type></entry>
8186         <entry>construct host mask for network</entry>
8187         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
8188         <entry><literal>0.0.0.3</literal></entry>
8189        </row>
8190        <row>
8191         <entry>
8192          <indexterm>
8193           <primary>masklen</primary>
8194          </indexterm>
8195          <literal><function>masklen(<type>inet</type>)</function></literal>
8196         </entry>
8197         <entry><type>int</type></entry>
8198         <entry>extract netmask length</entry>
8199         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
8200         <entry><literal>24</literal></entry>
8201        </row>
8202        <row>
8203         <entry>
8204          <indexterm>
8205           <primary>netmask</primary>
8206          </indexterm>
8207          <literal><function>netmask(<type>inet</type>)</function></literal>
8208         </entry>
8209         <entry><type>inet</type></entry>
8210         <entry>construct netmask for network</entry>
8211         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
8212         <entry><literal>255.255.255.0</literal></entry>
8213        </row>
8214        <row>
8215         <entry>
8216          <indexterm>
8217           <primary>network</primary>
8218          </indexterm>
8219          <literal><function>network(<type>inet</type>)</function></literal>
8220         </entry>
8221         <entry><type>cidr</type></entry>
8222         <entry>extract network part of address</entry>
8223         <entry><literal>network('192.168.1.5/24')</literal></entry>
8224         <entry><literal>192.168.1.0/24</literal></entry>
8225        </row>
8226        <row>
8227         <entry>
8228          <indexterm>
8229           <primary>set_masklen</primary>
8230          </indexterm>
8231          <literal><function>set_masklen(<type>inet</type>, <type>int</type>)</function></literal>
8232         </entry>
8233         <entry><type>inet</type></entry>
8234         <entry>set netmask length for <type>inet</type> value</entry>
8235         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
8236         <entry><literal>192.168.1.5/16</literal></entry>
8237        </row>
8238        <row>
8239         <entry><literal><function>set_masklen(<type>cidr</type>, <type>int</type>)</function></literal></entry>
8240         <entry><type>cidr</type></entry>
8241         <entry>set netmask length for <type>cidr</type> value</entry>
8242         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
8243         <entry><literal>192.168.0.0/16</literal></entry>
8244        </row>
8245        <row>
8246         <entry>
8247          <indexterm>
8248           <primary>text</primary>
8249          </indexterm>
8250          <literal><function>text(<type>inet</type>)</function></literal>
8251         </entry>
8252         <entry><type>text</type></entry>
8253         <entry>extract IP address and netmask length as text</entry>
8254         <entry><literal>text(inet '192.168.1.5')</literal></entry>
8255         <entry><literal>192.168.1.5/32</literal></entry>
8256        </row>
8257       </tbody>
8258      </tgroup>
8259     </table>
8260
8261   <para>
8262    Any <type>cidr</> value can be cast to <type>inet</> implicitly
8263    or explicitly; therefore, the functions shown above as operating on
8264    <type>inet</> also work on <type>cidr</> values.  (Where there are
8265    separate functions for <type>inet</> and <type>cidr</>, it is because
8266    the behavior should be different for the two cases.)
8267    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
8268    When this is done, any bits to the right of the netmask are silently zeroed
8269    to create a valid <type>cidr</> value.
8270    In addition,
8271    you can cast a text value to <type>inet</> or <type>cidr</>
8272    using normal casting syntax: for example,
8273    <literal>inet(<replaceable>expression</>)</literal> or
8274    <literal><replaceable>colname</>::cidr</literal>.
8275   </para>
8276
8277   <para>
8278    <xref linkend="macaddr-functions-table"> shows the functions
8279    available for use with the <type>macaddr</type> type.  The function
8280    <literal><function>trunc(<type>macaddr</type>)</function></literal> returns a MAC
8281    address with the last 3 bytes set to zero.  This can be used to
8282    associate the remaining prefix with a manufacturer.
8283   </para>
8284
8285     <table id="macaddr-functions-table">
8286      <title><type>macaddr</type> Functions</title>
8287      <tgroup cols="5">
8288       <thead>
8289        <row>
8290         <entry>Function</entry>
8291         <entry>Return Type</entry>
8292         <entry>Description</entry>
8293         <entry>Example</entry>
8294         <entry>Result</entry>
8295        </row>
8296       </thead>
8297       <tbody>
8298        <row>
8299         <entry>
8300          <indexterm>
8301           <primary>trunc</primary>
8302          </indexterm>
8303          <literal><function>trunc(<type>macaddr</type>)</function></literal>
8304         </entry>
8305         <entry><type>macaddr</type></entry>
8306         <entry>set last 3 bytes to zero</entry>
8307         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
8308         <entry><literal>12:34:56:00:00:00</literal></entry>
8309        </row>
8310       </tbody>
8311      </tgroup>
8312     </table>
8313
8314    <para>
8315     The <type>macaddr</type> type also supports the standard relational
8316     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
8317     lexicographical ordering, and the bitwise arithmetic operators
8318     (<literal>~</literal>, <literal>&amp;</literal> and <literal>|</literal>)
8319     for NOT, AND and OR.
8320    </para>
8321
8322   </sect1>
8323
8324
8325  <sect1 id="functions-textsearch">
8326   <title>Text Search Functions and Operators</title>
8327
8328    <indexterm zone="datatype-textsearch">
8329     <primary>full text search</primary>
8330     <secondary>functions and operators</secondary>
8331    </indexterm>
8332
8333    <indexterm zone="datatype-textsearch">
8334     <primary>text search</primary>
8335     <secondary>functions and operators</secondary>
8336    </indexterm>
8337
8338   <para>
8339    <xref linkend="textsearch-operators-table">,
8340    <xref linkend="textsearch-functions-table"> and
8341    <xref linkend="textsearch-functions-debug-table">
8342    summarize the functions and operators that are provided
8343    for full text searching.  See <xref linkend="textsearch"> for a detailed
8344    explanation of <productname>PostgreSQL</productname>'s text search
8345    facility.
8346   </para>
8347
8348     <table id="textsearch-operators-table">
8349      <title>Text Search Operators</title>
8350      <tgroup cols="4">
8351       <thead>
8352        <row>
8353         <entry>Operator</entry>
8354         <entry>Description</entry>
8355         <entry>Example</entry>
8356         <entry>Result</entry>
8357        </row>
8358       </thead>
8359       <tbody>
8360        <row>
8361         <entry> <literal>@@</literal> </entry>
8362         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
8363         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
8364         <entry><literal>t</literal></entry>
8365        </row>
8366        <row>
8367         <entry> <literal>@@@</literal> </entry>
8368         <entry>deprecated synonym for <literal>@@</></entry>
8369         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
8370         <entry><literal>t</literal></entry>
8371        </row>
8372        <row>
8373         <entry> <literal>||</literal> </entry>
8374         <entry>concatenate <type>tsvector</>s</entry>
8375         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
8376         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
8377        </row>
8378        <row>
8379         <entry> <literal>&amp;&amp;</literal> </entry>
8380         <entry>AND <type>tsquery</>s together</entry>
8381         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
8382         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
8383        </row>
8384        <row>
8385         <entry> <literal>||</literal> </entry>
8386         <entry>OR <type>tsquery</>s together</entry>
8387         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
8388         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
8389        </row>
8390        <row>
8391         <entry> <literal>!!</literal> </entry>
8392         <entry>negate a <type>tsquery</></entry>
8393         <entry><literal>!! 'cat'::tsquery</literal></entry>
8394         <entry><literal>!'cat'</literal></entry>
8395        </row>
8396        <row>
8397         <entry> <literal>@&gt;</literal> </entry>
8398         <entry><type>tsquery</> contains another ?</entry>
8399         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
8400         <entry><literal>f</literal></entry>
8401        </row>
8402        <row>
8403         <entry> <literal>&lt;@</literal> </entry>
8404         <entry><type>tsquery</> is contained in ?</entry>
8405         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
8406         <entry><literal>t</literal></entry>
8407        </row>
8408       </tbody>
8409      </tgroup>
8410     </table>
8411
8412     <note>
8413      <para>
8414       The <type>tsquery</> containment operators consider only the lexemes
8415       listed in the two queries, ignoring the combining operators.
8416      </para>
8417     </note>
8418
8419     <para>
8420      In addition to the operators shown in the table, the ordinary B-tree
8421      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
8422      for types <type>tsvector</> and <type>tsquery</>.  These are not very
8423      useful for text searching but allow, for example, unique indexes to be
8424      built on columns of these types.
8425     </para>
8426
8427     <table id="textsearch-functions-table">
8428      <title>Text Search Functions</title>
8429      <tgroup cols="5">
8430       <thead>
8431        <row>
8432         <entry>Function</entry>
8433         <entry>Return Type</entry>
8434         <entry>Description</entry>
8435         <entry>Example</entry>
8436         <entry>Result</entry>
8437        </row>
8438       </thead>
8439       <tbody>
8440        <row>
8441         <entry>
8442          <indexterm>
8443           <primary>get_current_ts_config</primary>
8444          </indexterm>
8445          <literal><function>get_current_ts_config()</function></literal>
8446         </entry>
8447         <entry><type>regconfig</type></entry>
8448         <entry>get default text search configuration</entry>
8449         <entry><literal>get_current_ts_config()</literal></entry>
8450         <entry><literal>english</literal></entry>
8451        </row>
8452        <row>
8453         <entry>
8454          <indexterm>
8455           <primary>length</primary>
8456          </indexterm>
8457          <literal><function>length(<type>tsvector</>)</function></literal>
8458         </entry>
8459         <entry><type>integer</type></entry>
8460         <entry>number of lexemes in <type>tsvector</></entry>
8461         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
8462         <entry><literal>3</literal></entry>
8463        </row>
8464        <row>
8465         <entry>
8466          <indexterm>
8467           <primary>numnode</primary>
8468          </indexterm>
8469          <literal><function>numnode(<type>tsquery</>)</function></literal>
8470         </entry>
8471         <entry><type>integer</type></entry>
8472         <entry>number of lexemes plus operators in <type>tsquery</></entry>
8473         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
8474         <entry><literal>5</literal></entry>
8475        </row>
8476        <row>
8477         <entry>
8478          <indexterm>
8479           <primary>plainto_tsquery</primary>
8480          </indexterm>
8481          <literal><function>plainto_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
8482         </entry>
8483         <entry><type>tsquery</type></entry>
8484         <entry>produce <type>tsquery</> ignoring punctuation</entry>
8485         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
8486         <entry><literal>'fat' &amp; 'rat'</literal></entry>
8487        </row>
8488        <row>
8489         <entry>
8490          <indexterm>
8491           <primary>querytree</primary>
8492          </indexterm>
8493          <literal><function>querytree(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</function></literal>
8494         </entry>
8495         <entry><type>text</type></entry>
8496         <entry>get indexable part of a <type>tsquery</></entry>
8497         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
8498         <entry><literal>'foo'</literal></entry>
8499        </row>
8500        <row>
8501         <entry>
8502          <indexterm>
8503           <primary>setweight</primary>
8504          </indexterm>
8505          <literal><function>setweight(<type>tsvector</>, <type>"char"</>)</function></literal>
8506         </entry>
8507         <entry><type>tsvector</type></entry>
8508         <entry>assign weight to each element of <type>tsvector</></entry>
8509         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
8510         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
8511        </row>
8512        <row>
8513         <entry>
8514          <indexterm>
8515           <primary>strip</primary>
8516          </indexterm>
8517          <literal><function>strip(<type>tsvector</>)</function></literal>
8518         </entry>
8519         <entry><type>tsvector</type></entry>
8520         <entry>remove positions and weights from <type>tsvector</></entry>
8521         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
8522         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
8523        </row>
8524        <row>
8525         <entry>
8526          <indexterm>
8527           <primary>to_tsquery</primary>
8528          </indexterm>
8529          <literal><function>to_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
8530         </entry>
8531         <entry><type>tsquery</type></entry>
8532         <entry>normalize words and convert to <type>tsquery</></entry>
8533         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
8534         <entry><literal>'fat' &amp; 'rat'</literal></entry>
8535        </row>
8536        <row>
8537         <entry>
8538          <indexterm>
8539           <primary>to_tsvector</primary>
8540          </indexterm>
8541          <literal><function>to_tsvector(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</function></literal>
8542         </entry>
8543         <entry><type>tsvector</type></entry>
8544         <entry>reduce document text to <type>tsvector</></entry>
8545         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
8546         <entry><literal>'fat':2 'rat':3</literal></entry>
8547        </row>
8548        <row>
8549         <entry>
8550          <indexterm>
8551           <primary>ts_headline</primary>
8552          </indexterm>
8553          <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>
8554         </entry>
8555         <entry><type>text</type></entry>
8556         <entry>display a query match</entry>
8557         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
8558         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
8559        </row>
8560        <row>
8561         <entry>
8562          <indexterm>
8563           <primary>ts_rank</primary>
8564          </indexterm>
8565          <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>
8566         </entry>
8567         <entry><type>float4</type></entry>
8568         <entry>rank document for query</entry>
8569         <entry><literal>ts_rank(textsearch, query)</literal></entry>
8570         <entry><literal>0.818</literal></entry>
8571        </row>
8572        <row>
8573         <entry>
8574          <indexterm>
8575           <primary>ts_rank_cd</primary>
8576          </indexterm>
8577          <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>
8578         </entry>
8579         <entry><type>float4</type></entry>
8580         <entry>rank document for query using cover density</entry>
8581         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
8582         <entry><literal>2.01317</literal></entry>
8583        </row>
8584        <row>
8585         <entry>
8586          <indexterm>
8587           <primary>ts_rewrite</primary>
8588          </indexterm>
8589          <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>
8590         </entry>
8591         <entry><type>tsquery</type></entry>
8592         <entry>replace target with substitute within query</entry>
8593         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
8594         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
8595        </row>
8596        <row>
8597         <entry><literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</function></literal></entry>
8598         <entry><type>tsquery</type></entry>
8599         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
8600         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
8601         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
8602        </row>
8603        <row>
8604         <entry>
8605          <indexterm>
8606           <primary>tsvector_update_trigger</primary>
8607          </indexterm>
8608          <literal><function>tsvector_update_trigger()</function></literal>
8609         </entry>
8610         <entry><type>trigger</type></entry>
8611         <entry>trigger function for automatic <type>tsvector</> column update</entry>
8612         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
8613         <entry><literal></literal></entry>
8614        </row>
8615        <row>
8616         <entry>
8617          <indexterm>
8618           <primary>tsvector_update_trigger_column</primary>
8619          </indexterm>
8620          <literal><function>tsvector_update_trigger_column()</function></literal>
8621         </entry>
8622         <entry><type>trigger</type></entry>
8623         <entry>trigger function for automatic <type>tsvector</> column update</entry>
8624         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
8625         <entry><literal></literal></entry>
8626        </row>
8627       </tbody>
8628      </tgroup>
8629     </table>
8630
8631   <note>
8632    <para>
8633     All the text search functions that accept an optional <type>regconfig</>
8634     argument will use the configuration specified by
8635     <xref linkend="guc-default-text-search-config">
8636     when that argument is omitted.
8637    </para>
8638   </note>
8639
8640   <para>
8641    The functions in
8642    <xref linkend="textsearch-functions-debug-table">
8643    are listed separately because they are not usually used in everyday text
8644    searching operations.  They are helpful for development and debugging
8645    of new text search configurations.
8646   </para>
8647
8648     <table id="textsearch-functions-debug-table">
8649      <title>Text Search Debugging Functions</title>
8650      <tgroup cols="5">
8651       <thead>
8652        <row>
8653         <entry>Function</entry>
8654         <entry>Return Type</entry>
8655         <entry>Description</entry>
8656         <entry>Example</entry>
8657         <entry>Result</entry>
8658        </row>
8659       </thead>
8660       <tbody>
8661        <row>
8662         <entry>
8663          <indexterm>
8664           <primary>ts_debug</primary>
8665          </indexterm>
8666          <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>
8667         </entry>
8668         <entry><type>setof record</type></entry>
8669         <entry>test a configuration</entry>
8670         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
8671         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
8672        </row>
8673        <row>
8674         <entry>
8675          <indexterm>
8676           <primary>ts_lexize</primary>
8677          </indexterm>
8678          <literal><function>ts_lexize(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</function></literal>
8679         </entry>
8680         <entry><type>text[]</type></entry>
8681         <entry>test a dictionary</entry>
8682         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
8683         <entry><literal>{star}</literal></entry>
8684        </row>
8685        <row>
8686         <entry>
8687          <indexterm>
8688           <primary>ts_parse</primary>
8689          </indexterm>
8690          <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>
8691         </entry>
8692         <entry><type>setof record</type></entry>
8693         <entry>test a parser</entry>
8694         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
8695         <entry><literal>(1,foo) ...</literal></entry>
8696        </row>
8697        <row>
8698         <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>
8699         <entry><type>setof record</type></entry>
8700         <entry>test a parser</entry>
8701         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
8702         <entry><literal>(1,foo) ...</literal></entry>
8703        </row>
8704        <row>
8705         <entry>
8706          <indexterm>
8707           <primary>ts_token_type</primary>
8708          </indexterm>
8709          <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>
8710         </entry>
8711         <entry><type>setof record</type></entry>
8712         <entry>get token types defined by parser</entry>
8713         <entry><literal>ts_token_type('default')</literal></entry>
8714         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8715        </row>
8716        <row>
8717         <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>
8718         <entry><type>setof record</type></entry>
8719         <entry>get token types defined by parser</entry>
8720         <entry><literal>ts_token_type(3722)</literal></entry>
8721         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8722        </row>
8723        <row>
8724         <entry>
8725          <indexterm>
8726           <primary>ts_stat</primary>
8727          </indexterm>
8728          <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>
8729         </entry>
8730         <entry><type>setof record</type></entry>
8731         <entry>get statistics of a <type>tsvector</> column</entry>
8732         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
8733         <entry><literal>(foo,10,15) ...</literal></entry>
8734        </row>
8735       </tbody>
8736      </tgroup>
8737     </table>
8738
8739  </sect1>
8740
8741
8742  <sect1 id="functions-xml">
8743   <title>XML Functions</title>
8744
8745   <para>
8746    The functions and function-like expressions described in this
8747    section operate on values of type <type>xml</type>.  Check <xref
8748    linkend="datatype-xml"> for information about the <type>xml</type>
8749    type.  The function-like expressions <function>xmlparse</function>
8750    and <function>xmlserialize</function> for converting to and from
8751    type <type>xml</type> are not repeated here.  Use of most of these
8752    functions requires the installation to have been built
8753    with <command>configure --with-libxml</>.
8754   </para>
8755
8756   <sect2 id="functions-producing-xml">
8757    <title>Producing XML Content</title>
8758
8759    <para>
8760     A set of functions and function-like expressions are available for
8761     producing XML content from SQL data.  As such, they are
8762     particularly suitable for formatting query results into XML
8763     documents for processing in client applications.
8764    </para>
8765
8766    <sect3>
8767     <title><literal>xmlcomment</literal></title>
8768
8769     <indexterm>
8770      <primary>xmlcomment</primary>
8771     </indexterm>
8772
8773 <synopsis>
8774 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8775 </synopsis>
8776
8777     <para>
8778      The function <function>xmlcomment</function> creates an XML value
8779      containing an XML comment with the specified text as content.
8780      The text cannot contain <quote><literal>--</literal></quote> or end with a
8781      <quote><literal>-</literal></quote> so that the resulting construct is a valid
8782      XML comment.  If the argument is null, the result is null.
8783     </para>
8784
8785     <para>
8786      Example:
8787 <screen><![CDATA[
8788 SELECT xmlcomment('hello');
8789
8790   xmlcomment
8791 --------------
8792  <!--hello-->
8793 ]]></screen>
8794     </para>
8795    </sect3>
8796
8797    <sect3>
8798     <title><literal>xmlconcat</literal></title>
8799
8800     <indexterm>
8801      <primary>xmlconcat</primary>
8802     </indexterm>
8803
8804 <synopsis>
8805 <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8806 </synopsis>
8807
8808     <para>
8809      The function <function>xmlconcat</function> concatenates a list
8810      of individual XML values to create a single value containing an
8811      XML content fragment.  Null values are omitted; the result is
8812      only null if there are no nonnull arguments.
8813     </para>
8814
8815     <para>
8816      Example:
8817 <screen><![CDATA[
8818 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8819
8820       xmlconcat
8821 ----------------------
8822  <abc/><bar>foo</bar>
8823 ]]></screen>
8824     </para>
8825
8826     <para>
8827      XML declarations, if present, are combined as follows.  If all
8828      argument values have the same XML version declaration, that
8829      version is used in the result, else no version is used.  If all
8830      argument values have the standalone declaration value
8831      <quote>yes</quote>, then that value is used in the result.  If
8832      all argument values have a standalone declaration value and at
8833      least one is <quote>no</quote>, then that is used in the result.
8834      Else the result will have no standalone declaration.  If the
8835      result is determined to require a standalone declaration but no
8836      version declaration, a version declaration with version 1.0 will
8837      be used because XML requires an XML declaration to contain a
8838      version declaration.  Encoding declarations are ignored and
8839      removed in all cases.
8840     </para>
8841
8842     <para>
8843      Example:
8844 <screen><![CDATA[
8845 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
8846
8847              xmlconcat
8848 -----------------------------------
8849  <?xml version="1.1"?><foo/><bar/>
8850 ]]></screen>
8851     </para>
8852    </sect3>
8853
8854    <sect3>
8855     <title><literal>xmlelement</literal></title>
8856
8857    <indexterm>
8858     <primary>xmlelement</primary>
8859    </indexterm>
8860
8861 <synopsis>
8862 <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>)
8863 </synopsis>
8864
8865     <para>
8866      The <function>xmlelement</function> expression produces an XML
8867      element with the given name, attributes, and content.
8868     </para>
8869
8870     <para>
8871      Examples:
8872 <screen><![CDATA[
8873 SELECT xmlelement(name foo);
8874
8875  xmlelement
8876 ------------
8877  <foo/>
8878
8879 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8880
8881     xmlelement
8882 ------------------
8883  <foo bar="xyz"/>
8884
8885 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8886
8887              xmlelement
8888 -------------------------------------
8889  <foo bar="2007-01-26">content</foo>
8890 ]]></screen>
8891     </para>
8892
8893     <para>
8894      Element and attribute names that are not valid XML names are
8895      escaped by replacing the offending characters by the sequence
8896      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8897      <replaceable>HHHH</replaceable> is the character's Unicode
8898      codepoint in hexadecimal notation.  For example:
8899 <screen><![CDATA[
8900 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
8901
8902             xmlelement
8903 ----------------------------------
8904  <foo_x0024_bar a_x0026_b="xyz"/>
8905 ]]></screen>
8906     </para>
8907
8908     <para>
8909      An explicit attribute name need not be specified if the attribute
8910      value is a column reference, in which case the column's name will
8911      be used as the attribute name by default.  In other cases, the
8912      attribute must be given an explicit name.  So this example is
8913      valid:
8914 <screen>
8915 CREATE TABLE test (a xml, b xml);
8916 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8917 </screen>
8918      But these are not:
8919 <screen>
8920 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8921 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8922 </screen>
8923     </para>
8924
8925     <para>
8926      Element content, if specified, will be formatted according to
8927      its data type.  If the content is itself of type <type>xml</type>,
8928      complex XML documents can be constructed.  For example:
8929 <screen><![CDATA[
8930 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8931                             xmlelement(name abc),
8932                             xmlcomment('test'),
8933                             xmlelement(name xyz));
8934
8935                   xmlelement
8936 ----------------------------------------------
8937  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
8938 ]]></screen>
8939
8940      Content of other types will be formatted into valid XML character
8941      data.  This means in particular that the characters &lt;, &gt;,
8942      and &amp; will be converted to entities.  Binary data (data type
8943      <type>bytea</type>) will be represented in base64 or hex
8944      encoding, depending on the setting of the configuration parameter
8945      <xref linkend="guc-xmlbinary">.  The particular behavior for
8946      individual data types is expected to evolve in order to align the
8947      SQL and PostgreSQL data types with the XML Schema specification,
8948      at which point a more precise description will appear.
8949     </para>
8950    </sect3>
8951
8952    <sect3>
8953     <title><literal>xmlforest</literal></title>
8954
8955    <indexterm>
8956     <primary>xmlforest</primary>
8957    </indexterm>
8958
8959 <synopsis>
8960 <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8961 </synopsis>
8962
8963     <para>
8964      The <function>xmlforest</function> expression produces an XML
8965      forest (sequence) of elements using the given names and content.
8966     </para>
8967
8968     <para>
8969      Examples:
8970 <screen><![CDATA[
8971 SELECT xmlforest('abc' AS foo, 123 AS bar);
8972
8973           xmlforest
8974 ------------------------------
8975  <foo>abc</foo><bar>123</bar>
8976
8977
8978 SELECT xmlforest(table_name, column_name)
8979 FROM information_schema.columns
8980 WHERE table_schema = 'pg_catalog';
8981
8982                                          xmlforest
8983 -------------------------------------------------------------------------------------------
8984  <table_name>pg_authid</table_name><column_name>rolname</column_name>
8985  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8986  ...
8987 ]]></screen>
8988
8989      As seen in the second example, the element name can be omitted if
8990      the content value is a column reference, in which case the column
8991      name is used by default.  Otherwise, a name must be specified.
8992     </para>
8993
8994     <para>
8995      Element names that are not valid XML names are escaped as shown
8996      for <function>xmlelement</function> above.  Similarly, content
8997      data is escaped to make valid XML content, unless it is already
8998      of type <type>xml</type>.
8999     </para>
9000
9001     <para>
9002      Note that XML forests are not valid XML documents if they consist
9003      of more than one element, so it might be useful to wrap
9004      <function>xmlforest</function> expressions in
9005      <function>xmlelement</function>.
9006     </para>
9007    </sect3>
9008
9009    <sect3>
9010     <title><literal>xmlpi</literal></title>
9011
9012    <indexterm>
9013     <primary>xmlpi</primary>
9014    </indexterm>
9015
9016 <synopsis>
9017 <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
9018 </synopsis>
9019
9020     <para>
9021      The <function>xmlpi</function> expression creates an XML
9022      processing instruction.  The content, if present, must not
9023      contain the character sequence <literal>?&gt;</literal>.
9024     </para>
9025
9026     <para>
9027      Example:
9028 <screen><![CDATA[
9029 SELECT xmlpi(name php, 'echo "hello world";');
9030
9031             xmlpi
9032 -----------------------------
9033  <?php echo "hello world";?>
9034 ]]></screen>
9035     </para>
9036    </sect3>
9037
9038    <sect3>
9039     <title><literal>xmlroot</literal></title>
9040
9041    <indexterm>
9042     <primary>xmlroot</primary>
9043    </indexterm>
9044
9045 <synopsis>
9046 <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
9047 </synopsis>
9048
9049     <para>
9050      The <function>xmlroot</function> expression alters the properties
9051      of the root node of an XML value.  If a version is specified,
9052      it replaces the value in the root node's version declaration; if a
9053      standalone setting is specified, it replaces the value in the
9054      root node's standalone declaration.
9055     </para>
9056
9057     <para>
9058 <screen><![CDATA[
9059 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
9060                version '1.0', standalone yes);
9061
9062                 xmlroot
9063 ----------------------------------------
9064  <?xml version="1.0" standalone="yes"?>
9065  <content>abc</content>
9066 ]]></screen>
9067     </para>
9068    </sect3>
9069
9070    <sect3 id="functions-xml-xmlagg">
9071     <title><literal>xmlagg</literal></title>
9072
9073     <indexterm>
9074      <primary>xmlagg</primary>
9075     </indexterm>
9076
9077 <synopsis>
9078 <function>xmlagg</function>(<replaceable>xml</replaceable>)
9079 </synopsis>
9080
9081     <para>
9082      The function <function>xmlagg</function> is, unlike the other
9083      functions described here, an aggregate function.  It concatenates the
9084      input values to the aggregate function call,
9085      much like <function>xmlconcat</function> does, except that concatenation
9086      occurs across rows rather than across expressions in a single row.
9087      See <xref linkend="functions-aggregate"> for additional information
9088      about aggregate functions.
9089     </para>
9090
9091     <para>
9092      Example:
9093 <screen><![CDATA[
9094 CREATE TABLE test (y int, x xml);
9095 INSERT INTO test VALUES (1, '<foo>abc</foo>');
9096 INSERT INTO test VALUES (2, '<bar/>');
9097 SELECT xmlagg(x) FROM test;
9098         xmlagg
9099 ----------------------
9100  <foo>abc</foo><bar/>
9101 ]]></screen>
9102     </para>
9103
9104     <para>
9105      To determine the order of the concatenation, an <literal>ORDER BY</>
9106      clause may be added to the aggregate call as described in
9107      <xref linkend="syntax-aggregates">. For example:
9108
9109 <screen><![CDATA[
9110 SELECT xmlagg(x ORDER BY y DESC) FROM test;
9111         xmlagg
9112 ----------------------
9113  <bar/><foo>abc</foo>
9114 ]]></screen>
9115     </para>
9116
9117     <para>
9118      The following non-standard approach used to be recommended
9119      in previous versions, and may still be useful in specific
9120      cases:
9121
9122 <screen><![CDATA[
9123 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
9124         xmlagg
9125 ----------------------
9126  <bar/><foo>abc</foo>
9127 ]]></screen>
9128     </para>
9129    </sect3>
9130    </sect2>
9131
9132    <sect2 id="functions-xml-predicates">
9133     <title>XML Predicates</title>
9134
9135     <para>
9136      The expressions described in this section check properties
9137      of <type>xml</type> values.
9138     </para>
9139
9140    <sect3>
9141     <title><literal>IS DOCUMENT</literal></title>
9142
9143     <indexterm>
9144      <primary>IS DOCUMENT</primary>
9145     </indexterm>
9146
9147 <synopsis>
9148 <replaceable>xml</replaceable> IS DOCUMENT
9149 </synopsis>
9150
9151     <para>
9152      The expression <literal>IS DOCUMENT</literal> returns true if the
9153      argument XML value is a proper XML document, false if it is not
9154      (that is, it is a content fragment), or null if the argument is
9155      null.  See <xref linkend="datatype-xml"> about the difference
9156      between documents and content fragments.
9157     </para>
9158    </sect3>
9159
9160    <sect3 id="xml-exists">
9161     <title><literal>XMLEXISTS</literal></title>
9162
9163     <indexterm>
9164      <primary>XMLEXISTS</primary>
9165     </indexterm>
9166
9167 <synopsis>
9168 <function>XMLEXISTS</function>(<replaceable>text</replaceable> PASSING <optional>BY REF</optional> <replaceable>xml</replaceable> <optional>BY REF</optional>)
9169 </synopsis>
9170
9171     <para>
9172      The function <function>xmlexists</function> returns true if the
9173      XPath expression in the first argument returns any nodes, and
9174      false otherwise.  (If either argument is null, the result is
9175      null.)
9176     </para>
9177
9178     <para>
9179      Example:
9180      <screen><![CDATA[
9181 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY REF '<towns><town>Toronto</town><town>Ottawa</town></towns>');
9182
9183  xmlexists
9184 ------------
9185  t
9186 (1 row)
9187 ]]></screen>
9188     </para>
9189
9190     <para>
9191      The <literal>BY REF</literal> clauses have no effect in
9192      PostgreSQL, but are allowed for SQL conformance and compatibility
9193      with other implementations.  Per SQL standard, the
9194      first <literal>BY REF</literal> is required, the second is
9195      optional.  Also note that the SQL standard specifies
9196      the <function>xmlexists</function> construct to take an XQuery
9197      expression as first argument, but PostgreSQL currently only
9198      supports XPath, which is a subset of XQuery.
9199     </para>
9200    </sect3>
9201
9202    <sect3 id="xml-is-well-formed">
9203     <title><literal>xml_is_well_formed</literal></title>
9204
9205     <indexterm>
9206      <primary>xml_is_well_formed</primary>
9207     </indexterm>
9208
9209     <indexterm>
9210      <primary>xml_is_well_formed_document</primary>
9211     </indexterm>
9212
9213     <indexterm>
9214      <primary>xml_is_well_formed_content</primary>
9215     </indexterm>
9216
9217 <synopsis>
9218 <function>xml_is_well_formed</function>(<replaceable>text</replaceable>)
9219 <function>xml_is_well_formed_document</function>(<replaceable>text</replaceable>)
9220 <function>xml_is_well_formed_content</function>(<replaceable>text</replaceable>)
9221 </synopsis>
9222
9223     <para>
9224      These functions check whether a <type>text</> string is well-formed XML,
9225      returning a Boolean result.
9226      <function>xml_is_well_formed_document</function> checks for a well-formed
9227      document, while <function>xml_is_well_formed_content</function> checks
9228      for well-formed content.  <function>xml_is_well_formed</function> does
9229      the former if the <xref linkend="guc-xmloption"> configuration
9230      parameter is set to <literal>DOCUMENT</>, or the latter if it is set to
9231      <literal>CONTENT</>.  This means that
9232      <function>xml_is_well_formed</function> is useful for seeing whether
9233      a simple cast to type <type>xml</> will succeed, whereas the other two
9234      functions are useful for seeing whether the corresponding variants of
9235      <function>XMLPARSE</> will succeed.
9236     </para>
9237
9238     <para>
9239      Examples:
9240
9241 <screen><![CDATA[
9242 SET xmloption TO DOCUMENT;
9243 SELECT xml_is_well_formed('<>');
9244  xml_is_well_formed 
9245 --------------------
9246  f
9247 (1 row)
9248
9249 SELECT xml_is_well_formed('<abc/>');
9250  xml_is_well_formed 
9251 --------------------
9252  t
9253 (1 row)
9254
9255 SET xmloption TO CONTENT;
9256 SELECT xml_is_well_formed('abc');
9257  xml_is_well_formed 
9258 --------------------
9259  t
9260 (1 row)
9261
9262 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
9263  xml_is_well_formed_document 
9264 -----------------------------
9265  t
9266 (1 row)
9267
9268 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
9269  xml_is_well_formed_document 
9270 -----------------------------
9271  f
9272 (1 row)
9273 ]]></screen>
9274
9275      The last example shows that the checks include whether
9276      namespaces are correctly matched.
9277     </para>
9278    </sect3>
9279   </sect2>
9280
9281   <sect2 id="functions-xml-processing">
9282    <title>Processing XML</title>
9283
9284    <indexterm>
9285     <primary>XPath</primary>
9286    </indexterm>
9287
9288    <para>
9289     To process values of data type <type>xml</type>, PostgreSQL offers
9290     the functions <function>xpath</function> and
9291     <function>xpath_exists</function>, which evaluate XPath 1.0
9292     expressions.
9293    </para>
9294
9295 <synopsis>
9296 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9297 </synopsis>
9298
9299    <para>
9300     The function <function>xpath</function> evaluates the XPath
9301     expression <replaceable>xpath</replaceable> (a <type>text</> value)
9302     against the XML value
9303     <replaceable>xml</replaceable>.  It returns an array of XML values
9304     corresponding to the node set produced by the XPath expression.
9305     If the XPath expression returns a scalar value rather than a node set,
9306     a single-element array is returned.
9307    </para>
9308
9309   <para>
9310     The second argument must be a well formed XML document. In particular,
9311     it must have a single root node element.
9312   </para>
9313
9314    <para>
9315     The optional third argument of the function is an array of namespace
9316     mappings.  This array should be a two-dimensional <type>text</> array with
9317     the length of the second axis being equal to 2 (i.e., it should be an
9318     array of arrays, each of which consists of exactly 2 elements).
9319     The first element of each array entry is the namespace name (alias), the
9320     second the namespace URI. It is not required that aliases provided in
9321     this array be the same as those being used in the XML document itself (in
9322     other words, both in the XML document and in the <function>xpath</function>
9323     function context, aliases are <emphasis>local</>).
9324    </para>
9325
9326    <para>
9327     Example:
9328 <screen><![CDATA[
9329 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9330              ARRAY[ARRAY['my', 'http://example.com']]);
9331
9332  xpath  
9333 --------
9334  {test}
9335 (1 row)
9336 ]]></screen>
9337    </para>
9338
9339    <para>
9340     To deal with default (anonymous) namespaces, do something like this:
9341 <screen><![CDATA[
9342 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
9343              ARRAY[ARRAY['mydefns', 'http://example.com']]);
9344
9345  xpath
9346 --------
9347  {test}
9348 (1 row)
9349 ]]></screen>
9350    </para>
9351
9352    <indexterm>
9353     <primary>xpath_exists</primary>
9354    </indexterm>
9355
9356 <synopsis>
9357 <function>xpath_exists</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9358 </synopsis>
9359
9360    <para>
9361     The function <function>xpath_exists</function> is a specialized form
9362     of the <function>xpath</function> function.  Instead of returning the
9363     individual XML values that satisfy the XPath, this function returns a
9364     Boolean indicating whether the query was satisfied or not.  This
9365     function is equivalent to the standard <literal>XMLEXISTS</> predicate,
9366     except that it also offers support for a namespace mapping argument.
9367    </para>
9368
9369    <para>
9370     Example:
9371 <screen><![CDATA[
9372 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9373                      ARRAY[ARRAY['my', 'http://example.com']]);
9374
9375  xpath_exists  
9376 --------------
9377  t
9378 (1 row)
9379 ]]></screen>
9380    </para>
9381   </sect2>
9382
9383   <sect2 id="functions-xml-mapping">
9384    <title>Mapping Tables to XML</title>
9385
9386    <indexterm zone="functions-xml-mapping">
9387     <primary>XML export</primary>
9388    </indexterm>
9389
9390    <para>
9391     The following functions map the contents of relational tables to
9392     XML values.  They can be thought of as XML export functionality:
9393 <synopsis>
9394 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9395 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
9396 cursor_to_xml(cursor refcursor, count int, nulls boolean,
9397               tableforest boolean, targetns text)
9398 </synopsis>
9399     The return type of each function is <type>xml</type>.
9400    </para>
9401
9402    <para>
9403     <function>table_to_xml</function> maps the content of the named
9404     table, passed as parameter <parameter>tbl</parameter>.  The
9405     <type>regclass</type> type accepts strings identifying tables using the
9406     usual notation, including optional schema qualifications and
9407     double quotes.  <function>query_to_xml</function> executes the
9408     query whose text is passed as parameter
9409     <parameter>query</parameter> and maps the result set.
9410     <function>cursor_to_xml</function> fetches the indicated number of
9411     rows from the cursor specified by the parameter
9412     <parameter>cursor</parameter>.  This variant is recommended if
9413     large tables have to be mapped, because the result value is built
9414     up in memory by each function.
9415    </para>
9416
9417    <para>
9418     If <parameter>tableforest</parameter> is false, then the resulting
9419     XML document looks like this:
9420 <screen><![CDATA[
9421 <tablename>
9422   <row>
9423     <columnname1>data</columnname1>
9424     <columnname2>data</columnname2>
9425   </row>
9426
9427   <row>
9428     ...
9429   </row>
9430
9431   ...
9432 </tablename>
9433 ]]></screen>
9434
9435     If <parameter>tableforest</parameter> is true, the result is an
9436     XML content fragment that looks like this:
9437 <screen><![CDATA[
9438 <tablename>
9439   <columnname1>data</columnname1>
9440   <columnname2>data</columnname2>
9441 </tablename>
9442
9443 <tablename>
9444   ...
9445 </tablename>
9446
9447 ...
9448 ]]></screen>
9449
9450     If no table name is available, that is, when mapping a query or a
9451     cursor, the string <literal>table</literal> is used in the first
9452     format, <literal>row</literal> in the second format.
9453    </para>
9454
9455    <para>
9456     The choice between these formats is up to the user.  The first
9457     format is a proper XML document, which will be important in many
9458     applications.  The second format tends to be more useful in the
9459     <function>cursor_to_xml</function> function if the result values are to be
9460     reassembled into one document later on.  The functions for
9461     producing XML content discussed above, in particular
9462     <function>xmlelement</function>, can be used to alter the results
9463     to taste.
9464    </para>
9465
9466    <para>
9467     The data values are mapped in the same way as described for the
9468     function <function>xmlelement</function> above.
9469    </para>
9470
9471    <para>
9472     The parameter <parameter>nulls</parameter> determines whether null
9473     values should be included in the output.  If true, null values in
9474     columns are represented as:
9475 <screen><![CDATA[
9476 <columnname xsi:nil="true"/>
9477 ]]></screen>
9478     where <literal>xsi</literal> is the XML namespace prefix for XML
9479     Schema Instance.  An appropriate namespace declaration will be
9480     added to the result value.  If false, columns containing null
9481     values are simply omitted from the output.
9482    </para>
9483
9484    <para>
9485     The parameter <parameter>targetns</parameter> specifies the
9486     desired XML namespace of the result.  If no particular namespace
9487     is wanted, an empty string should be passed.
9488    </para>
9489
9490    <para>
9491     The following functions return XML Schema documents describing the
9492     mappings performed by the corresponding functions above:
9493 <synopsis>
9494 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9495 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9496 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
9497 </synopsis>
9498     It is essential that the same parameters are passed in order to
9499     obtain matching XML data mappings and XML Schema documents.
9500    </para>
9501
9502    <para>
9503     The following functions produce XML data mappings and the
9504     corresponding XML Schema in one document (or forest), linked
9505     together.  They can be useful where self-contained and
9506     self-describing results are wanted:
9507 <synopsis>
9508 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9509 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9510 </synopsis>
9511    </para>
9512
9513    <para>
9514     In addition, the following functions are available to produce
9515     analogous mappings of entire schemas or the entire current
9516     database:
9517 <synopsis>
9518 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
9519 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9520 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9521
9522 database_to_xml(nulls boolean, tableforest boolean, targetns text)
9523 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
9524 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
9525 </synopsis>
9526
9527     Note that these potentially produce a lot of data, which needs to
9528     be built up in memory.  When requesting content mappings of large
9529     schemas or databases, it might be worthwhile to consider mapping the
9530     tables separately instead, possibly even through a cursor.
9531    </para>
9532
9533    <para>
9534     The result of a schema content mapping looks like this:
9535
9536 <screen><![CDATA[
9537 <schemaname>
9538
9539 table1-mapping
9540
9541 table2-mapping
9542
9543 ...
9544
9545 </schemaname>]]></screen>
9546
9547     where the format of a table mapping depends on the
9548     <parameter>tableforest</parameter> parameter as explained above.
9549    </para>
9550
9551    <para>
9552     The result of a database content mapping looks like this:
9553
9554 <screen><![CDATA[
9555 <dbname>
9556
9557 <schema1name>
9558   ...
9559 </schema1name>
9560
9561 <schema2name>
9562   ...
9563 </schema2name>
9564
9565 ...
9566
9567 </dbname>]]></screen>
9568
9569     where the schema mapping is as above.
9570    </para>
9571
9572    <para>
9573     As an example of using the output produced by these functions,
9574     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
9575     converts the output of
9576     <function>table_to_xml_and_xmlschema</function> to an HTML
9577     document containing a tabular rendition of the table data.  In a
9578     similar manner, the results from these functions can be
9579     converted into other XML-based formats.
9580    </para>
9581
9582    <figure id="xslt-xml-html">
9583     <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
9584 <programlisting><![CDATA[
9585 <?xml version="1.0"?>
9586 <xsl:stylesheet version="1.0"
9587     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
9588     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
9589     xmlns="http://www.w3.org/1999/xhtml"
9590 >
9591
9592   <xsl:output method="xml"
9593       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
9594       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
9595       indent="yes"/>
9596
9597   <xsl:template match="/*">
9598     <xsl:variable name="schema" select="//xsd:schema"/>
9599     <xsl:variable name="tabletypename"
9600                   select="$schema/xsd:element[@name=name(current())]/@type"/>
9601     <xsl:variable name="rowtypename"
9602                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
9603
9604     <html>
9605       <head>
9606         <title><xsl:value-of select="name(current())"/></title>
9607       </head>
9608       <body>
9609         <table>
9610           <tr>
9611             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
9612               <th><xsl:value-of select="."/></th>
9613             </xsl:for-each>
9614           </tr>
9615
9616           <xsl:for-each select="row">
9617             <tr>
9618               <xsl:for-each select="*">
9619                 <td><xsl:value-of select="."/></td>
9620               </xsl:for-each>
9621             </tr>
9622           </xsl:for-each>
9623         </table>
9624       </body>
9625     </html>
9626   </xsl:template>
9627
9628 </xsl:stylesheet>
9629 ]]></programlisting>
9630    </figure>
9631   </sect2>
9632  </sect1>
9633
9634  <sect1 id="functions-json">
9635   <title>JSON Functions</title>
9636
9637   <indexterm zone="functions-json">
9638     <primary>JSON</primary>
9639     <secondary>Functions and operators</secondary>
9640   </indexterm>
9641
9642   <para>
9643    <xref linkend="functions-json-table"> shows the functions that are available
9644    for creating JSON (see <xref linkend="datatype-json">) data.
9645   </para>
9646
9647   <table id="functions-json-table">
9648     <title>JSON Support Functions</title>
9649     <tgroup cols="4">
9650      <thead>
9651       <row>
9652        <entry>Function</entry>
9653        <entry>Description</entry>
9654        <entry>Example</entry>
9655        <entry>Example Result</entry>
9656       </row>
9657      </thead>
9658      <tbody>
9659       <row>
9660        <entry>
9661          <indexterm>
9662           <primary>array_to_json</primary>
9663          </indexterm>
9664          <literal>array_to_json(anyarray [, pretty_bool])</literal>
9665        </entry>
9666        <entry>
9667          Returns the array as JSON. A PostgreSQL multidimensional array
9668          becomes a JSON array of arrays. Line feeds will be added between
9669          dimension 1 elements if <parameter>pretty_bool</parameter> is true.
9670        </entry>
9671        <entry><literal>array_to_json('{{1,5},{99,100}}'::int[])</literal></entry>
9672        <entry><literal>[[1,5],[99,100]]</literal></entry>
9673       </row>
9674       <row>
9675        <entry>
9676          <indexterm>
9677           <primary>row_to_json</primary>
9678          </indexterm>
9679          <literal>row_to_json(record [, pretty_bool])</literal>
9680        </entry>
9681        <entry>
9682          Returns the row as JSON. Line feeds will be added between level
9683          1 elements if <parameter>pretty_bool</parameter> is true.
9684        </entry>
9685        <entry><literal>row_to_json(row(1,'foo'))</literal></entry>
9686        <entry><literal>{"f1":1,"f2":"foo"}</literal></entry>
9687       </row>
9688      </tbody>
9689     </tgroup>
9690    </table>
9691
9692  </sect1>
9693
9694  <sect1 id="functions-sequence">
9695   <title>Sequence Manipulation Functions</title>
9696
9697   <indexterm>
9698    <primary>sequence</primary>
9699   </indexterm>
9700   <indexterm>
9701    <primary>nextval</primary>
9702   </indexterm>
9703   <indexterm>
9704    <primary>currval</primary>
9705   </indexterm>
9706   <indexterm>
9707    <primary>lastval</primary>
9708   </indexterm>
9709   <indexterm>
9710    <primary>setval</primary>
9711   </indexterm>
9712
9713   <para>
9714    This section describes <productname>PostgreSQL</productname>'s
9715    functions for operating on <firstterm>sequence objects</firstterm>.
9716    Sequence objects (also called sequence generators or just
9717    sequences) are special single-row tables created with <xref
9718    linkend="sql-createsequence">.
9719    A sequence object is usually used to generate unique identifiers
9720    for rows of a table.  The sequence functions, listed in <xref
9721    linkend="functions-sequence-table">, provide simple, multiuser-safe
9722    methods for obtaining successive sequence values from sequence
9723    objects.
9724   </para>
9725
9726    <table id="functions-sequence-table">
9727     <title>Sequence Functions</title>
9728     <tgroup cols="3">
9729      <thead>
9730       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
9731      </thead>
9732
9733      <tbody>
9734       <row>
9735         <entry><literal><function>currval(<type>regclass</type>)</function></literal></entry>
9736         <entry><type>bigint</type></entry>
9737         <entry>Return value most recently obtained with
9738         <function>nextval</function> for specified sequence</entry>
9739       </row>
9740       <row>
9741         <entry><literal><function>lastval()</function></literal></entry>
9742         <entry><type>bigint</type></entry>
9743         <entry>Return value most recently obtained with
9744         <function>nextval</function> for any sequence</entry>
9745       </row>
9746       <row>
9747         <entry><literal><function>nextval(<type>regclass</type>)</function></literal></entry>
9748         <entry><type>bigint</type></entry>
9749         <entry>Advance sequence and return new value</entry>
9750       </row>
9751       <row>
9752         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>)</function></literal></entry>
9753         <entry><type>bigint</type></entry>
9754         <entry>Set sequence's current value</entry>
9755       </row>
9756       <row>
9757         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</function></literal></entry>
9758         <entry><type>bigint</type></entry>
9759         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
9760       </row>
9761      </tbody>
9762     </tgroup>
9763    </table>
9764
9765   <para>
9766    The sequence to be operated on by a sequence function is specified by
9767    a <type>regclass</> argument, which is simply the OID of the sequence in the
9768    <structname>pg_class</> system catalog.  You do not have to look up the
9769    OID by hand, however, since the <type>regclass</> data type's input
9770    converter will do the work for you.  Just write the sequence name enclosed
9771    in single quotes so that it looks like a literal constant.  For
9772    compatibility with the handling of ordinary
9773    <acronym>SQL</acronym> names, the string will be converted to lower case
9774    unless it contains double quotes around the sequence name.  Thus:
9775 <programlisting>
9776 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
9777 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
9778 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
9779 </programlisting>
9780    The sequence name can be schema-qualified if necessary:
9781 <programlisting>
9782 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
9783 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
9784 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
9785 </programlisting>
9786    See <xref linkend="datatype-oid"> for more information about
9787    <type>regclass</>.
9788   </para>
9789
9790   <note>
9791    <para>
9792     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
9793     sequence functions were of type <type>text</>, not <type>regclass</>, and
9794     the above-described conversion from a text string to an OID value would
9795     happen at run time during each call.  For backward compatibility, this
9796     facility still exists, but internally it is now handled as an implicit
9797     coercion from <type>text</> to <type>regclass</> before the function is
9798     invoked.
9799    </para>
9800
9801    <para>
9802     When you write the argument of a sequence function as an unadorned
9803     literal string, it becomes a constant of type <type>regclass</>.
9804     Since this is really just an OID, it will track the originally
9805     identified sequence despite later renaming, schema reassignment,
9806     etc.  This <quote>early binding</> behavior is usually desirable for
9807     sequence references in column defaults and views.  But sometimes you might
9808     want <quote>late binding</> where the sequence reference is resolved
9809     at run time.  To get late-binding behavior, force the constant to be
9810     stored as a <type>text</> constant instead of <type>regclass</>:
9811 <programlisting>
9812 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
9813 </programlisting>
9814     Note that late binding was the only behavior supported in
9815     <productname>PostgreSQL</productname> releases before 8.1, so you
9816     might need to do this to preserve the semantics of old applications.
9817    </para>
9818
9819    <para>
9820     Of course, the argument of a sequence function can be an expression
9821     as well as a constant.  If it is a text expression then the implicit
9822     coercion will result in a run-time lookup.
9823    </para>
9824   </note>
9825
9826   <para>
9827    The available sequence functions are:
9828
9829     <variablelist>
9830      <varlistentry>
9831       <term><function>nextval</function></term>
9832       <listitem>
9833        <para>
9834         Advance the sequence object to its next value and return that
9835         value.  This is done atomically: even if multiple sessions
9836         execute <function>nextval</function> concurrently, each will safely receive
9837         a distinct sequence value.
9838        </para>
9839
9840        <para>
9841         If a sequence object has been created with default parameters,
9842         successive <function>nextval</function> calls will return successive
9843         values beginning with 1.  Other behaviors can be obtained by using
9844         special parameters in the <xref linkend="sql-createsequence"> command;
9845         see its command reference page for more information.
9846        </para>
9847
9848        <important>
9849         <para>
9850          To avoid blocking concurrent transactions that obtain numbers from the
9851          same sequence, a <function>nextval</function> operation is never
9852          rolled back; that is, once a value has been fetched it is considered
9853          used, even if the transaction that did the
9854          <function>nextval</function> later aborts.  This means that aborted
9855          transactions might leave unused <quote>holes</quote> in the sequence
9856          of assigned values.
9857         </para>
9858        </important>
9859
9860       </listitem>
9861      </varlistentry>
9862
9863      <varlistentry>
9864       <term><function>currval</function></term>
9865       <listitem>
9866        <para>
9867         Return the value most recently obtained by <function>nextval</function>
9868         for this sequence in the current session.  (An error is
9869         reported if <function>nextval</function> has never been called for this
9870         sequence in this session.)  Because this is returning
9871         a session-local value, it gives a predictable answer whether or not
9872         other sessions have executed <function>nextval</function> since the
9873         current session did.
9874        </para>
9875       </listitem>
9876      </varlistentry>
9877
9878      <varlistentry>
9879       <term><function>lastval</function></term>
9880       <listitem>
9881        <para>
9882         Return the value most recently returned by
9883         <function>nextval</> in the current session. This function is
9884         identical to <function>currval</function>, except that instead
9885         of taking the sequence name as an argument it fetches the
9886         value of the last sequence used by <function>nextval</function>
9887         in the current session. It is an error to call
9888         <function>lastval</function> if <function>nextval</function>
9889         has not yet been called in the current session.
9890        </para>
9891       </listitem>
9892      </varlistentry>
9893
9894      <varlistentry>
9895       <term><function>setval</function></term>
9896       <listitem>
9897        <para>
9898         Reset the sequence object's counter value.  The two-parameter
9899         form sets the sequence's <literal>last_value</literal> field to the
9900         specified value and sets its <literal>is_called</literal> field to
9901         <literal>true</literal>, meaning that the next
9902         <function>nextval</function> will advance the sequence before
9903         returning a value.  The value reported by <function>currval</> is
9904         also set to the specified value.  In the three-parameter form,
9905         <literal>is_called</literal> can be set to either <literal>true</literal>
9906         or <literal>false</literal>.  <literal>true</> has the same effect as
9907         the two-parameter form. If it is set to <literal>false</literal>, the
9908         next <function>nextval</function> will return exactly the specified
9909         value, and sequence advancement commences with the following
9910         <function>nextval</function>.  Furthermore, the value reported by
9911         <function>currval</> is not changed in this case (this is a change
9912         from pre-8.3 behavior).  For example,
9913
9914 <screen>
9915 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
9916 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
9917 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
9918 </screen>
9919
9920         The result returned by <function>setval</function> is just the value of its
9921         second argument.
9922        </para>
9923        <important>
9924         <para>
9925          Because sequences are non-transactional, changes made by
9926          <function>setval</function> are not undone if the transaction rolls
9927          back.
9928         </para>
9929        </important>
9930       </listitem>
9931      </varlistentry>
9932     </variablelist>
9933   </para>
9934
9935  </sect1>
9936
9937
9938  <sect1 id="functions-conditional">
9939   <title>Conditional Expressions</title>
9940
9941   <indexterm>
9942    <primary>CASE</primary>
9943   </indexterm>
9944
9945   <indexterm>
9946    <primary>conditional expression</primary>
9947   </indexterm>
9948
9949   <para>
9950    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
9951    available in <productname>PostgreSQL</productname>.
9952   </para>
9953
9954   <tip>
9955    <para>
9956     If your needs go beyond the capabilities of these conditional
9957     expressions, you might want to consider writing a stored procedure
9958     in a more expressive programming language.
9959    </para>
9960   </tip>
9961
9962   <sect2 id="functions-case">
9963    <title><literal>CASE</></title>
9964
9965   <para>
9966    The <acronym>SQL</acronym> <token>CASE</token> expression is a
9967    generic conditional expression, similar to if/else statements in
9968    other programming languages:
9969
9970 <synopsis>
9971 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
9972      <optional>WHEN ...</optional>
9973      <optional>ELSE <replaceable>result</replaceable></optional>
9974 END
9975 </synopsis>
9976
9977    <token>CASE</token> clauses can be used wherever
9978    an expression is valid.  Each <replaceable>condition</replaceable> is an
9979    expression that returns a <type>boolean</type> result.  If the condition's
9980    result is true, the value of the <token>CASE</token> expression is the
9981    <replaceable>result</replaceable> that follows the condition, and the
9982    remainder of the <token>CASE</token> expression is not processed.  If the
9983    condition's result is not true, any subsequent <token>WHEN</token> clauses
9984    are examined in the same manner.  If no <token>WHEN</token>
9985    <replaceable>condition</replaceable> yields true, the value of the
9986    <token>CASE</> expression is the <replaceable>result</replaceable> of the
9987    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
9988    omitted and no condition is true, the result is null.
9989   </para>
9990
9991    <para>
9992     An example:
9993 <screen>
9994 SELECT * FROM test;
9995
9996  a
9997 ---
9998  1
9999  2
10000  3
10001
10002
10003 SELECT a,
10004        CASE WHEN a=1 THEN 'one'
10005             WHEN a=2 THEN 'two'
10006             ELSE 'other'
10007        END
10008     FROM test;
10009
10010  a | case
10011 ---+-------
10012  1 | one
10013  2 | two
10014  3 | other
10015 </screen>
10016    </para>
10017
10018   <para>
10019    The data types of all the <replaceable>result</replaceable>
10020    expressions must be convertible to a single output type.
10021    See <xref linkend="typeconv-union-case"> for more details.
10022   </para>
10023
10024   <para>
10025    There is a <quote>simple</> form of <token>CASE</token> expression
10026    that is a variant of the general form above:
10027
10028 <synopsis>
10029 CASE <replaceable>expression</replaceable>
10030     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
10031     <optional>WHEN ...</optional>
10032     <optional>ELSE <replaceable>result</replaceable></optional>
10033 END
10034 </synopsis>
10035
10036    The first
10037    <replaceable>expression</replaceable> is computed, then compared to
10038    each of the <replaceable>value</replaceable> expressions in the
10039    <token>WHEN</token> clauses until one is found that is equal to it.  If
10040    no match is found, the <replaceable>result</replaceable> of the
10041    <token>ELSE</token> clause (or a null value) is returned.  This is similar
10042    to the <function>switch</function> statement in C.
10043   </para>
10044
10045    <para>
10046     The example above can be written using the simple
10047     <token>CASE</token> syntax:
10048 <screen>
10049 SELECT a,
10050        CASE a WHEN 1 THEN 'one'
10051               WHEN 2 THEN 'two'
10052               ELSE 'other'
10053        END
10054     FROM test;
10055
10056  a | case
10057 ---+-------
10058  1 | one
10059  2 | two
10060  3 | other
10061 </screen>
10062    </para>
10063
10064    <para>
10065     A <token>CASE</token> expression does not evaluate any subexpressions
10066     that are not needed to determine the result.  For example, this is a
10067     possible way of avoiding a division-by-zero failure:
10068 <programlisting>
10069 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
10070 </programlisting>
10071    </para>
10072   </sect2>
10073
10074   <sect2 id="functions-coalesce-nvl-ifnull">
10075    <title><literal>COALESCE</></title>
10076
10077   <indexterm>
10078    <primary>COALESCE</primary>
10079   </indexterm>
10080
10081   <indexterm>
10082    <primary>NVL</primary>
10083   </indexterm>
10084
10085   <indexterm>
10086    <primary>IFNULL</primary>
10087   </indexterm>
10088
10089 <synopsis>
10090 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10091 </synopsis>
10092
10093   <para>
10094    The <function>COALESCE</function> function returns the first of its
10095    arguments that is not null.  Null is returned only if all arguments
10096    are null.  It is often used to substitute a default value for
10097    null values when data is retrieved for display, for example:
10098 <programlisting>
10099 SELECT COALESCE(description, short_description, '(none)') ...
10100 </programlisting>
10101    This returns <varname>description</> if it is not null, otherwise
10102    <varname>short_description</> if it is not null, otherwise <literal>(none)</>.
10103   </para>
10104
10105    <para>
10106     Like a <token>CASE</token> expression, <function>COALESCE</function> only
10107     evaluates the arguments that are needed to determine the result;
10108     that is, arguments to the right of the first non-null argument are
10109     not evaluated.  This SQL-standard function provides capabilities similar
10110     to <function>NVL</> and <function>IFNULL</>, which are used in some other
10111     database systems.
10112    </para>
10113   </sect2>
10114
10115   <sect2 id="functions-nullif">
10116    <title><literal>NULLIF</></title>
10117
10118   <indexterm>
10119    <primary>NULLIF</primary>
10120   </indexterm>
10121
10122 <synopsis>
10123 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
10124 </synopsis>
10125
10126   <para>
10127    The <function>NULLIF</function> function returns a null value if
10128    <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
10129    otherwise it returns <replaceable>value1</replaceable>.
10130    This can be used to perform the inverse operation of the
10131    <function>COALESCE</function> example given above:
10132 <programlisting>
10133 SELECT NULLIF(value, '(none)') ...
10134 </programlisting>
10135   </para>
10136   <para>
10137    In this example, if <literal>value</literal> is <literal>(none)</>,
10138    null is returned, otherwise the value of <literal>value</literal>
10139    is returned.
10140   </para>
10141
10142   </sect2>
10143
10144   <sect2 id="functions-greatest-least">
10145    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
10146
10147   <indexterm>
10148    <primary>GREATEST</primary>
10149   </indexterm>
10150   <indexterm>
10151    <primary>LEAST</primary>
10152   </indexterm>
10153
10154 <synopsis>
10155 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10156 </synopsis>
10157 <synopsis>
10158 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10159 </synopsis>
10160
10161    <para>
10162     The <function>GREATEST</> and <function>LEAST</> functions select the
10163     largest or smallest value from a list of any number of expressions.
10164     The expressions must all be convertible to a common data type, which
10165     will be the type of the result
10166     (see <xref linkend="typeconv-union-case"> for details).  NULL values
10167     in the list are ignored.  The result will be NULL only if all the
10168     expressions evaluate to NULL.
10169    </para>
10170
10171    <para>
10172     Note that <function>GREATEST</> and <function>LEAST</> are not in
10173     the SQL standard, but are a common extension.  Some other databases
10174     make them return NULL if any argument is NULL, rather than only when
10175     all are NULL.
10176    </para>
10177   </sect2>
10178  </sect1>
10179
10180  <sect1 id="functions-array">
10181   <title>Array Functions and Operators</title>
10182
10183   <para>
10184    <xref linkend="array-operators-table"> shows the operators
10185    available for array types.
10186   </para>
10187
10188     <table id="array-operators-table">
10189      <title>Array Operators</title>
10190      <tgroup cols="4">
10191       <thead>
10192        <row>
10193         <entry>Operator</entry>
10194         <entry>Description</entry>
10195         <entry>Example</entry>
10196         <entry>Result</entry>
10197        </row>
10198       </thead>
10199       <tbody>
10200        <row>
10201         <entry> <literal>=</literal> </entry>
10202         <entry>equal</entry>
10203         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
10204         <entry><literal>t</literal></entry>
10205        </row>
10206
10207        <row>
10208         <entry> <literal>&lt;&gt;</literal> </entry>
10209         <entry>not equal</entry>
10210         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
10211         <entry><literal>t</literal></entry>
10212        </row>
10213
10214        <row>
10215         <entry> <literal>&lt;</literal> </entry>
10216         <entry>less than</entry>
10217         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
10218         <entry><literal>t</literal></entry>
10219        </row>
10220
10221        <row>
10222         <entry> <literal>&gt;</literal> </entry>
10223         <entry>greater than</entry>
10224         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
10225         <entry><literal>t</literal></entry>
10226        </row>
10227
10228        <row>
10229         <entry> <literal>&lt;=</literal> </entry>
10230         <entry>less than or equal</entry>
10231         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
10232         <entry><literal>t</literal></entry>
10233        </row>
10234
10235        <row>
10236         <entry> <literal>&gt;=</literal> </entry>
10237         <entry>greater than or equal</entry>
10238         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
10239         <entry><literal>t</literal></entry>
10240        </row>
10241
10242        <row>
10243         <entry> <literal>@&gt;</literal> </entry>
10244         <entry>contains</entry>
10245         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
10246         <entry><literal>t</literal></entry>
10247        </row>
10248
10249        <row>
10250         <entry> <literal>&lt;@</literal> </entry>
10251         <entry>is contained by</entry>
10252         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
10253         <entry><literal>t</literal></entry>
10254        </row>
10255
10256        <row>
10257         <entry> <literal>&amp;&amp;</literal> </entry>
10258         <entry>overlap (have elements in common)</entry>
10259         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
10260         <entry><literal>t</literal></entry>
10261        </row>
10262
10263        <row>
10264         <entry> <literal>||</literal> </entry>
10265         <entry>array-to-array concatenation</entry>
10266         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
10267         <entry><literal>{1,2,3,4,5,6}</literal></entry>
10268        </row>
10269
10270        <row>
10271         <entry> <literal>||</literal> </entry>
10272         <entry>array-to-array concatenation</entry>
10273         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
10274         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
10275        </row>
10276
10277        <row>
10278         <entry> <literal>||</literal> </entry>
10279         <entry>element-to-array concatenation</entry>
10280         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
10281         <entry><literal>{3,4,5,6}</literal></entry>
10282        </row>
10283
10284        <row>
10285         <entry> <literal>||</literal> </entry>
10286         <entry>array-to-element concatenation</entry>
10287         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
10288         <entry><literal>{4,5,6,7}</literal></entry>
10289        </row>
10290       </tbody>
10291      </tgroup>
10292     </table>
10293
10294   <para>
10295    Array comparisons compare the array contents element-by-element,
10296    using the default B-tree comparison function for the element data type.
10297    In multidimensional arrays the elements are visited in row-major order
10298    (last subscript varies most rapidly).
10299    If the contents of two arrays are equal but the dimensionality is
10300    different, the first difference in the dimensionality information
10301    determines the sort order.  (This is a change from versions of
10302    <productname>PostgreSQL</> prior to 8.2: older versions would claim
10303    that two arrays with the same contents were equal, even if the
10304    number of dimensions or subscript ranges were different.)
10305   </para>
10306
10307   <para>
10308    See <xref linkend="arrays"> for more details about array operator
10309    behavior.  See <xref linkend="indexes-types"> for more details about
10310    which operators support indexed operations.
10311   </para>
10312
10313   <para>
10314    <xref linkend="array-functions-table"> shows the functions
10315    available for use with array types. See <xref linkend="arrays">
10316    for more information  and examples of the use of these functions.
10317   </para>
10318
10319   <indexterm>
10320     <primary>array_append</primary>
10321   </indexterm>
10322   <indexterm>
10323     <primary>array_cat</primary>
10324   </indexterm>
10325   <indexterm>
10326     <primary>array_ndims</primary>
10327   </indexterm>
10328   <indexterm>
10329     <primary>array_dims</primary>
10330   </indexterm>
10331   <indexterm>
10332     <primary>array_fill</primary>
10333   </indexterm>
10334   <indexterm>
10335     <primary>array_length</primary>
10336   </indexterm>
10337   <indexterm>
10338     <primary>array_lower</primary>
10339   </indexterm>
10340   <indexterm>
10341     <primary>array_prepend</primary>
10342   </indexterm>
10343   <indexterm>
10344     <primary>array_remove</primary>
10345   </indexterm>
10346   <indexterm>
10347     <primary>array_replace</primary>
10348   </indexterm>
10349   <indexterm>
10350     <primary>array_to_string</primary>
10351   </indexterm>
10352  <indexterm>
10353     <primary>array_upper</primary>
10354   </indexterm>
10355   <indexterm>
10356     <primary>string_to_array</primary>
10357   </indexterm>
10358   <indexterm>
10359     <primary>unnest</primary>
10360   </indexterm>
10361
10362     <table id="array-functions-table">
10363      <title>Array Functions</title>
10364      <tgroup cols="5">
10365       <thead>
10366        <row>
10367         <entry>Function</entry>
10368         <entry>Return Type</entry>
10369         <entry>Description</entry>
10370         <entry>Example</entry>
10371         <entry>Result</entry>
10372        </row>
10373       </thead>
10374       <tbody>
10375        <row>
10376         <entry>
10377          <literal>
10378           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
10379          </literal>
10380         </entry>
10381         <entry><type>anyarray</type></entry>
10382         <entry>append an element to the end of an array</entry>
10383         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
10384         <entry><literal>{1,2,3}</literal></entry>
10385        </row>
10386        <row>
10387         <entry>
10388          <literal>
10389           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
10390          </literal>
10391         </entry>
10392         <entry><type>anyarray</type></entry>
10393         <entry>concatenate two arrays</entry>
10394         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
10395         <entry><literal>{1,2,3,4,5}</literal></entry>
10396        </row>
10397        <row>
10398         <entry>
10399          <literal>
10400           <function>array_ndims</function>(<type>anyarray</type>)
10401          </literal>
10402         </entry>
10403         <entry><type>int</type></entry>
10404         <entry>returns the number of dimensions of the array</entry>
10405         <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
10406         <entry><literal>2</literal></entry>
10407        </row>
10408        <row>
10409         <entry>
10410          <literal>
10411           <function>array_dims</function>(<type>anyarray</type>)
10412          </literal>
10413         </entry>
10414         <entry><type>text</type></entry>
10415         <entry>returns a text representation of array's dimensions</entry>
10416         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
10417         <entry><literal>[1:2][1:3]</literal></entry>
10418        </row>
10419        <row>
10420         <entry>
10421          <literal>
10422           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
10423           <optional>, <type>int[]</type></optional>)
10424          </literal>
10425         </entry>
10426         <entry><type>anyarray</type></entry>
10427         <entry>returns an array initialized with supplied value and
10428          dimensions, optionally with lower bounds other than 1</entry>
10429         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
10430         <entry><literal>[2:4]={7,7,7}</literal></entry>
10431        </row>
10432        <row>
10433         <entry>
10434          <literal>
10435           <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
10436          </literal>
10437         </entry>
10438         <entry><type>int</type></entry>
10439         <entry>returns the length of the requested array dimension</entry>
10440         <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
10441         <entry><literal>3</literal></entry>
10442        </row>
10443        <row>
10444         <entry>
10445          <literal>
10446           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
10447          </literal>
10448         </entry>
10449         <entry><type>int</type></entry>
10450         <entry>returns lower bound of the requested array dimension</entry>
10451         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
10452         <entry><literal>0</literal></entry>
10453        </row>
10454        <row>
10455         <entry>
10456          <literal>
10457           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
10458          </literal>
10459         </entry>
10460         <entry><type>anyarray</type></entry>
10461         <entry>append an element to the beginning of an array</entry>
10462         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
10463         <entry><literal>{1,2,3}</literal></entry>
10464        </row>
10465        <row>
10466         <entry>
10467          <literal>
10468           <function>array_remove</function>(<type>anyarray</type>, <type>anyelement</type>)
10469          </literal>
10470         </entry>
10471         <entry><type>anyarray</type></entry>
10472         <entry>remove all elements equal to the given value from the array
10473          (array must be one-dimensional)</entry>
10474         <entry><literal>array_remove(ARRAY[1,2,3,2], 2)</literal></entry>
10475         <entry><literal>{1,3}</literal></entry>
10476        </row>
10477        <row>
10478         <entry>
10479          <literal>
10480           <function>array_replace</function>(<type>anyarray</type>, <type>anyelement</type>, <type>anyelement</type>)
10481          </literal>
10482         </entry>
10483         <entry><type>anyarray</type></entry>
10484         <entry>replace each array element equal to the given value with a new value</entry>
10485         <entry><literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal></entry>
10486         <entry><literal>{1,2,3,4}</literal></entry>
10487        </row>
10488        <row>
10489         <entry>
10490          <literal>
10491           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type> <optional>, <type>text</type></optional>)
10492          </literal>
10493         </entry>
10494         <entry><type>text</type></entry>
10495         <entry>concatenates array elements using supplied delimiter and
10496          optional null string</entry>
10497         <entry><literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal></entry>
10498         <entry><literal>1,2,3,*,5</literal></entry>
10499        </row>
10500        <row>
10501         <entry>
10502          <literal>
10503           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
10504          </literal>
10505         </entry>
10506         <entry><type>int</type></entry>
10507         <entry>returns upper bound of the requested array dimension</entry>
10508         <entry><literal>array_upper(ARRAY[1,8,3,7], 1)</literal></entry>
10509         <entry><literal>4</literal></entry>
10510        </row>
10511        <row>
10512         <entry>
10513          <literal>
10514           <function>string_to_array</function>(<type>text</type>, <type>text</type> <optional>, <type>text</type></optional>)
10515          </literal>
10516         </entry>
10517         <entry><type>text[]</type></entry>
10518         <entry>splits string into array elements using supplied delimiter and
10519          optional null string</entry>
10520         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~', 'yy')</literal></entry>
10521         <entry><literal>{xx,NULL,zz}</literal></entry>
10522        </row>
10523        <row>
10524         <entry>
10525          <literal>
10526           <function>unnest</function>(<type>anyarray</type>)
10527          </literal>
10528         </entry>
10529         <entry><type>setof anyelement</type></entry>
10530         <entry>expand an array to a set of rows</entry>
10531         <entry><literal>unnest(ARRAY[1,2])</literal></entry>
10532         <entry><literallayout class="monospaced">1
10533 2</literallayout>(2 rows)</entry>
10534        </row>
10535       </tbody>
10536      </tgroup>
10537     </table>
10538
10539    <para>
10540     In <function>string_to_array</function>, if the delimiter parameter is
10541     NULL, each character in the input string will become a separate element in
10542     the resulting array.  If the delimiter is an empty string, then the entire
10543     input string is returned as a one-element array.  Otherwise the input
10544     string is split at each occurrence of the delimiter string.
10545    </para>
10546
10547    <para>
10548     In <function>string_to_array</function>, if the null-string parameter
10549     is omitted or NULL, none of the substrings of the input will be replaced
10550     by NULL.
10551     In <function>array_to_string</function>, if the null-string parameter
10552     is omitted or NULL, any null elements in the array are simply skipped
10553     and not represented in the output string.
10554    </para>
10555
10556    <note>
10557     <para>
10558      There are two differences in the behavior of <function>string_to_array</>
10559      from pre-9.1 versions of <productname>PostgreSQL</>.
10560      First, it will return an empty (zero-element) array rather than NULL when
10561      the input string is of zero length.  Second, if the delimiter string is
10562      NULL, the function splits the input into individual characters, rather
10563      than returning NULL as before.
10564     </para>
10565    </note>
10566
10567    <para>
10568     See also <xref linkend="functions-aggregate"> about the aggregate
10569     function <function>array_agg</function> for use with arrays.
10570    </para>
10571   </sect1>
10572
10573  <sect1 id="functions-range">
10574   <title>Range Functions and Operators</title>
10575
10576   <para>
10577    See <xref linkend="rangetypes"> for an overview of range types.
10578   </para>
10579
10580   <para>
10581    <xref linkend="range-operators-table"> shows the operators
10582    available for range types.
10583   </para>
10584
10585     <table id="range-operators-table">
10586      <title>Range Operators</title>
10587      <tgroup cols="4">
10588       <thead>
10589        <row>
10590         <entry>Operator</entry>
10591         <entry>Description</entry>
10592         <entry>Example</entry>
10593         <entry>Result</entry>
10594        </row>
10595       </thead>
10596       <tbody>
10597        <row>
10598         <entry> <literal>=</literal> </entry>
10599         <entry>equal</entry>
10600         <entry><literal>int4range(1,5) = '[1,4]'::int4range</literal></entry>
10601         <entry><literal>t</literal></entry>
10602        </row>
10603
10604        <row>
10605         <entry> <literal>&lt;&gt;</literal> </entry>
10606         <entry>not equal</entry>
10607         <entry><literal>numrange(1.1,2.2) &lt;&gt; numrange(1.1,2.3)</literal></entry>
10608         <entry><literal>t</literal></entry>
10609        </row>
10610
10611        <row>
10612         <entry> <literal>&lt;</literal> </entry>
10613         <entry>less than</entry>
10614         <entry><literal>int4range(1,10) &lt; int4range(2,3)</literal></entry>
10615         <entry><literal>t</literal></entry>
10616        </row>
10617
10618        <row>
10619         <entry> <literal>&gt;</literal> </entry>
10620         <entry>greater than</entry>
10621         <entry><literal>int4range(1,10) &gt; int4range(1,5)</literal></entry>
10622         <entry><literal>t</literal></entry>
10623        </row>
10624
10625        <row>
10626         <entry> <literal>&lt;=</literal> </entry>
10627         <entry>less than or equal</entry>
10628         <entry><literal>numrange(1.1,2.2) &lt;= numrange(1.1,2.2)</literal></entry>
10629         <entry><literal>t</literal></entry>
10630        </row>
10631
10632        <row>
10633         <entry> <literal>&gt;=</literal> </entry>
10634         <entry>greater than or equal</entry>
10635         <entry><literal>numrange(1.1,2.2) &gt;= numrange(1.1,2.0)</literal></entry>
10636         <entry><literal>t</literal></entry>
10637        </row>
10638
10639        <row>
10640         <entry> <literal>@&gt;</literal> </entry>
10641         <entry>contains range</entry>
10642         <entry><literal>int4range(2,4) @&gt; int4range(2,3)</literal></entry>
10643         <entry><literal>t</literal></entry>
10644        </row>
10645
10646        <row>
10647         <entry> <literal>@&gt;</literal> </entry>
10648         <entry>contains element</entry>
10649         <entry><literal>'[2011-01-01,2011-03-01)'::tsrange @&gt; '2011-01-10'::timestamp</literal></entry>
10650         <entry><literal>t</literal></entry>
10651        </row>
10652
10653        <row>
10654         <entry> <literal>&lt;@</literal> </entry>
10655         <entry>range is contained by</entry>
10656         <entry><literal>int4range(2,4) &lt;@ int4range(1,7)</literal></entry>
10657         <entry><literal>t</literal></entry>
10658        </row>
10659
10660        <row>
10661         <entry> <literal>&lt;@</literal> </entry>
10662         <entry>element is contained by</entry>
10663         <entry><literal>42 &lt;@ int4range(1,7)</literal></entry>
10664         <entry><literal>f</literal></entry>
10665        </row>
10666
10667        <row>
10668         <entry> <literal>&amp;&amp;</literal> </entry>
10669         <entry>overlap (have points in common)</entry>
10670         <entry><literal>int8range(3,7) &amp;&amp; int8range(4,12)</literal></entry>
10671         <entry><literal>t</literal></entry>
10672        </row>
10673
10674        <row>
10675         <entry> <literal>&lt;&lt;</literal> </entry>
10676         <entry>strictly left of</entry>
10677         <entry><literal>int8range(1,10) &lt;&lt; int8range(100,110)</literal></entry>
10678         <entry><literal>t</literal></entry>
10679        </row>
10680
10681        <row>
10682         <entry> <literal>&gt;&gt;</literal> </entry>
10683         <entry>strictly right of</entry>
10684         <entry><literal>int8range(50,60) &gt;&gt; int8range(20,30)</literal></entry>
10685         <entry><literal>t</literal></entry>
10686        </row>
10687
10688        <row>
10689         <entry> <literal>&amp;&lt;</literal> </entry>
10690         <entry>does not extend to the right of</entry>
10691         <entry><literal>int8range(1,20) &amp;&lt; int8range(18,20)</literal></entry>
10692         <entry><literal>t</literal></entry>
10693        </row>
10694
10695        <row>
10696         <entry> <literal>&amp;&gt;</literal> </entry>
10697         <entry>does not extend to the left of</entry>
10698         <entry><literal>int8range(7,20) &amp;&gt; int8range(5,10)</literal></entry>
10699         <entry><literal>t</literal></entry>
10700        </row>
10701
10702        <row>
10703         <entry> <literal>-|-</literal> </entry>
10704         <entry>is adjacent to</entry>
10705         <entry><literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal></entry>
10706         <entry><literal>t</literal></entry>
10707        </row>
10708
10709        <row>
10710         <entry> <literal>+</literal> </entry>
10711         <entry>union</entry>
10712         <entry><literal>numrange(5,15) + numrange(10,20)</literal></entry>
10713         <entry><literal>[5,20)</literal></entry>
10714        </row>
10715
10716        <row>
10717         <entry> <literal>*</literal> </entry>
10718         <entry>intersection</entry>
10719         <entry><literal>int8range(5,15) * int8range(10,20)</literal></entry>
10720         <entry><literal>[10,15)</literal></entry>
10721        </row>
10722
10723        <row>
10724         <entry> <literal>-</literal> </entry>
10725         <entry>difference</entry>
10726         <entry><literal>int8range(5,15) - int8range(10,20)</literal></entry>
10727         <entry><literal>[5,10)</literal></entry>
10728        </row>
10729
10730       </tbody>
10731      </tgroup>
10732     </table>
10733
10734   <para>
10735    The simple comparison operators <literal>&lt;</literal>,
10736    <literal>&gt;</literal>, <literal>&lt;=</literal>, and
10737    <literal>&gt;=</literal> compare the lower bounds first, and only if those
10738    are equal, compare the upper bounds.  These comparisons are not usually
10739    very useful for ranges, but are provided to allow B-tree indexes to be
10740    constructed on ranges.
10741   </para>
10742
10743   <para>
10744    The left-of/right-of/adjacent operators always return false when an empty
10745    range is involved; that is, an empty range is not considered to be either
10746    before or after any other range.
10747   </para>
10748
10749   <para>
10750    The union and difference operators will fail if the resulting range would
10751    need to contain two disjoint sub-ranges, as such a range cannot be
10752    represented.
10753   </para>
10754
10755   <para>
10756    <xref linkend="range-functions-table"> shows the functions
10757    available for use with range types.
10758   </para>
10759
10760   <indexterm>
10761     <primary>lower</primary>
10762   </indexterm>
10763   <indexterm>
10764     <primary>upper</primary>
10765   </indexterm>
10766   <indexterm>
10767     <primary>isempty</primary>
10768   </indexterm>
10769   <indexterm>
10770     <primary>lower_inc</primary>
10771   </indexterm>
10772   <indexterm>
10773     <primary>upper_inc</primary>
10774   </indexterm>
10775   <indexterm>
10776     <primary>lower_inf</primary>
10777   </indexterm>
10778   <indexterm>
10779     <primary>upper_inf</primary>
10780   </indexterm>
10781
10782     <table id="range-functions-table">
10783      <title>Range Functions</title>
10784      <tgroup cols="5">
10785       <thead>
10786        <row>
10787         <entry>Function</entry>
10788         <entry>Return Type</entry>
10789         <entry>Description</entry>
10790         <entry>Example</entry>
10791         <entry>Result</entry>
10792        </row>
10793       </thead>
10794       <tbody>
10795        <row>
10796         <entry>
10797          <literal>
10798           <function>lower</function>(<type>anyrange</type>)
10799          </literal>
10800         </entry>
10801         <entry>range's element type</entry>
10802         <entry>lower bound of range</entry>
10803         <entry><literal>lower(numrange(1.1,2.2))</literal></entry>
10804         <entry><literal>1.1</literal></entry>
10805        </row>
10806        <row>
10807         <entry>
10808          <literal>
10809           <function>upper</function>(<type>anyrange</type>)
10810          </literal>
10811         </entry>
10812         <entry>range's element type</entry>
10813         <entry>upper bound of range</entry>
10814         <entry><literal>upper(numrange(1.1,2.2))</literal></entry>
10815         <entry><literal>2.2</literal></entry>
10816        </row>
10817        <row>
10818         <entry>
10819          <literal>
10820           <function>isempty</function>(<type>anyrange</type>)
10821          </literal>
10822         </entry>
10823         <entry><type>boolean</type></entry>
10824         <entry>is the range empty?</entry>
10825         <entry><literal>isempty(numrange(1.1,2.2))</literal></entry>
10826         <entry><literal>false</literal></entry>
10827        </row>
10828        <row>
10829         <entry>
10830          <literal>
10831           <function>lower_inc</function>(<type>anyrange</type>)
10832          </literal>
10833         </entry>
10834         <entry><type>boolean</type></entry>
10835         <entry>is the lower bound inclusive?</entry>
10836         <entry><literal>lower_inc(numrange(1.1,2.2))</literal></entry>
10837         <entry><literal>true</literal></entry>
10838        </row>
10839        <row>
10840         <entry>
10841          <literal>
10842           <function>upper_inc</function>(<type>anyrange</type>)
10843          </literal>
10844         </entry>
10845         <entry><type>boolean</type></entry>
10846         <entry>is the upper bound inclusive?</entry>
10847         <entry><literal>upper_inc(numrange(1.1,2.2))</literal></entry>
10848         <entry><literal>false</literal></entry>
10849        </row>
10850        <row>
10851         <entry>
10852          <literal>
10853           <function>lower_inf</function>(<type>anyrange</type>)
10854          </literal>
10855         </entry>
10856         <entry><type>boolean</type></entry>
10857         <entry>is the lower bound infinite?</entry>
10858         <entry><literal>lower_inf('(,)'::daterange)</literal></entry>
10859         <entry><literal>true</literal></entry>
10860        </row>
10861        <row>
10862         <entry>
10863          <literal>
10864           <function>upper_inf</function>(<type>anyrange</type>)
10865          </literal>
10866         </entry>
10867         <entry><type>boolean</type></entry>
10868         <entry>is the upper bound infinite?</entry>
10869         <entry><literal>upper_inf('(,)'::daterange)</literal></entry>
10870         <entry><literal>true</literal></entry>
10871        </row>
10872       </tbody>
10873      </tgroup>
10874     </table>
10875
10876   <para>
10877    The <function>lower</> and  <function>upper</> functions return null
10878    if the range is empty or the requested bound is infinite.
10879    The <function>lower_inc</function>, <function>upper_inc</function>,
10880    <function>lower_inf</function>, and <function>upper_inf</function>
10881    functions all return false for an empty range.
10882   </para>
10883   </sect1>
10884
10885  <sect1 id="functions-aggregate">
10886   <title>Aggregate Functions</title>
10887
10888   <indexterm zone="functions-aggregate">
10889    <primary>aggregate function</primary>
10890    <secondary>built-in</secondary>
10891   </indexterm>
10892
10893   <para>
10894    <firstterm>Aggregate functions</firstterm> compute a single result
10895    from a set of input values.  The built-in aggregate functions
10896    are listed in
10897    <xref linkend="functions-aggregate-table"> and
10898    <xref linkend="functions-aggregate-statistics-table">.
10899    The special syntax considerations for aggregate
10900    functions are explained in <xref linkend="syntax-aggregates">.
10901    Consult <xref linkend="tutorial-agg"> for additional introductory
10902    information.
10903   </para>
10904
10905   <table id="functions-aggregate-table">
10906    <title>General-Purpose Aggregate Functions</title>
10907
10908    <tgroup cols="4">
10909     <thead>
10910      <row>
10911       <entry>Function</entry>
10912       <entry>Argument Type(s)</entry>
10913       <entry>Return Type</entry>
10914       <entry>Description</entry>
10915      </row>
10916     </thead>
10917
10918     <tbody>
10919      <row>
10920       <entry>
10921        <indexterm>
10922         <primary>array_agg</primary>
10923        </indexterm>
10924        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
10925       </entry>
10926       <entry>
10927        any
10928       </entry>
10929       <entry>
10930        array of the argument type
10931       </entry>
10932       <entry>input values, including nulls, concatenated into an array</entry>
10933      </row>
10934
10935      <row>
10936       <entry>
10937        <indexterm>
10938         <primary>average</primary>
10939        </indexterm>
10940        <indexterm>
10941         <primary>avg</primary>
10942        </indexterm>
10943        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
10944       </entry>
10945       <entry>
10946        <type>smallint</type>, <type>int</type>,
10947        <type>bigint</type>, <type>real</type>, <type>double
10948        precision</type>, <type>numeric</type>, or <type>interval</type>
10949       </entry>
10950       <entry>
10951        <type>numeric</type> for any integer-type argument,
10952        <type>double precision</type> for a floating-point argument,
10953        otherwise the same as the argument data type
10954       </entry>
10955       <entry>the average (arithmetic mean) of all input values</entry>
10956      </row>
10957
10958      <row>
10959       <entry>
10960        <indexterm>
10961         <primary>bit_and</primary>
10962        </indexterm>
10963        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
10964       </entry>
10965       <entry>
10966        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
10967        <type>bit</type>
10968       </entry>
10969       <entry>
10970         same as argument data type
10971       </entry>
10972       <entry>the bitwise AND of all non-null input values, or null if none</entry>
10973      </row>
10974
10975      <row>
10976       <entry>
10977        <indexterm>
10978         <primary>bit_or</primary>
10979        </indexterm>
10980        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
10981       </entry>
10982       <entry>
10983        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
10984        <type>bit</type>
10985       </entry>
10986       <entry>
10987         same as argument data type
10988       </entry>
10989       <entry>the bitwise OR of all non-null input values, or null if none</entry>
10990      </row>
10991
10992      <row>
10993       <entry>
10994        <indexterm>
10995         <primary>bool_and</primary>
10996        </indexterm>
10997        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
10998       </entry>
10999       <entry>
11000        <type>bool</type>
11001       </entry>
11002       <entry>
11003        <type>bool</type>
11004       </entry>
11005       <entry>true if all input values are true, otherwise false</entry>
11006      </row>
11007
11008      <row>
11009       <entry>
11010        <indexterm>
11011         <primary>bool_or</primary>
11012        </indexterm>
11013        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
11014       </entry>
11015       <entry>
11016        <type>bool</type>
11017       </entry>
11018       <entry>
11019        <type>bool</type>
11020       </entry>
11021       <entry>true if at least one input value is true, otherwise false</entry>
11022      </row>
11023
11024      <row>
11025       <entry>
11026        <indexterm>
11027         <primary>count</primary>
11028        </indexterm>
11029        <function>count(*)</function>
11030       </entry>
11031       <entry></entry>
11032       <entry><type>bigint</type></entry>
11033       <entry>number of input rows</entry>
11034      </row>
11035
11036      <row>
11037       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
11038       <entry>any</entry>
11039       <entry><type>bigint</type></entry>
11040       <entry>
11041        number of input rows for which the value of <replaceable
11042        class="parameter">expression</replaceable> is not null
11043       </entry>
11044      </row>
11045
11046      <row>
11047       <entry>
11048        <indexterm>
11049         <primary>every</primary>
11050        </indexterm>
11051        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
11052       </entry>
11053       <entry>
11054        <type>bool</type>
11055       </entry>
11056       <entry>
11057        <type>bool</type>
11058       </entry>
11059       <entry>equivalent to <function>bool_and</function></entry>
11060      </row>
11061
11062      <row>
11063       <entry>
11064        <indexterm>
11065         <primary>max</primary>
11066        </indexterm>
11067        <function>max(<replaceable class="parameter">expression</replaceable>)</function>
11068       </entry>
11069       <entry>any array, numeric, string, or date/time type</entry>
11070       <entry>same as argument type</entry>
11071       <entry>
11072        maximum value of <replaceable
11073        class="parameter">expression</replaceable> across all input
11074        values
11075       </entry>
11076      </row>
11077
11078      <row>
11079       <entry>
11080        <indexterm>
11081         <primary>min</primary>
11082        </indexterm>
11083        <function>min(<replaceable class="parameter">expression</replaceable>)</function>
11084       </entry>
11085       <entry>any array, numeric, string, or date/time type</entry>
11086       <entry>same as argument type</entry>
11087       <entry>
11088        minimum value of <replaceable
11089        class="parameter">expression</replaceable> across all input
11090        values
11091       </entry>
11092      </row>
11093
11094      <row>
11095       <entry>
11096        <indexterm>
11097         <primary>string_agg</primary>
11098        </indexterm>
11099        <function>
11100          string_agg(<replaceable class="parameter">expression</replaceable>,
11101                     <replaceable class="parameter">delimiter</replaceable>)
11102        </function>
11103       </entry>
11104       <entry>
11105        (<type>text</type>, <type>text</type>) or (<type>bytea</type>, <type>bytea</type>)
11106       </entry>
11107       <entry>
11108        same as argument types
11109       </entry>
11110       <entry>input values concatenated into a string, separated by delimiter</entry>
11111      </row>
11112
11113      <row>
11114       <entry>
11115        <indexterm>
11116         <primary>sum</primary>
11117        </indexterm>
11118        <function>sum(<replaceable class="parameter">expression</replaceable>)</function>
11119       </entry>
11120       <entry>
11121        <type>smallint</type>, <type>int</type>,
11122        <type>bigint</type>, <type>real</type>, <type>double
11123        precision</type>, <type>numeric</type>, or
11124        <type>interval</type>
11125       </entry>
11126       <entry>
11127        <type>bigint</type> for <type>smallint</type> or
11128        <type>int</type> arguments, <type>numeric</type> for
11129        <type>bigint</type> arguments, <type>double precision</type>
11130        for floating-point arguments, otherwise the same as the
11131        argument data type
11132       </entry>
11133       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
11134      </row>
11135
11136      <row>
11137       <entry>
11138        <indexterm>
11139         <primary>xmlagg</primary>
11140        </indexterm>
11141        <function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
11142       </entry>
11143       <entry>
11144        <type>xml</type>
11145       </entry>
11146       <entry>
11147        <type>xml</type>
11148       </entry>
11149       <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
11150      </row>
11151     </tbody>
11152    </tgroup>
11153   </table>
11154
11155   <para>
11156    It should be noted that except for <function>count</function>,
11157    these functions return a null value when no rows are selected.  In
11158    particular, <function>sum</function> of no rows returns null, not
11159    zero as one might expect, and <function>array_agg</function>
11160    returns null rather than an empty array when there are no input
11161    rows.  The <function>coalesce</function> function can be used to
11162    substitute zero or an empty array for null when necessary.
11163   </para>
11164
11165   <note>
11166     <indexterm>
11167       <primary>ANY</primary>
11168     </indexterm>
11169     <indexterm>
11170       <primary>SOME</primary>
11171     </indexterm>
11172     <para>
11173       Boolean aggregates <function>bool_and</function> and
11174       <function>bool_or</function> correspond to standard SQL aggregates
11175       <function>every</function> and <function>any</function> or
11176       <function>some</function>.
11177       As for <function>any</function> and <function>some</function>,
11178       it seems that there is an ambiguity built into the standard syntax:
11179 <programlisting>
11180 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
11181 </programlisting>
11182       Here <function>ANY</function> can be considered either as introducing
11183       a subquery, or as being an aggregate function, if the subquery
11184       returns one row with a Boolean value.
11185       Thus the standard name cannot be given to these aggregates.
11186     </para>
11187   </note>
11188
11189   <note>
11190    <para>
11191     Users accustomed to working with other SQL database management
11192     systems might be disappointed by the performance of the
11193     <function>count</function> aggregate when it is applied to the
11194     entire table. A query like:
11195 <programlisting>
11196 SELECT count(*) FROM sometable;
11197 </programlisting>
11198     will require effort proportional to the size of the table:
11199     <productname>PostgreSQL</productname> will need to scan either the
11200     entire table or the entirety of an index which includes all rows in
11201     the table.
11202    </para>
11203   </note>
11204
11205   <para>
11206    The aggregate functions <function>array_agg</function>,
11207    <function>string_agg</function>,
11208    and <function>xmlagg</function>, as well as similar user-defined
11209    aggregate functions, produce meaningfully different result values
11210    depending on the order of the input values.  This ordering is
11211    unspecified by default, but can be controlled by writing an
11212    <literal>ORDER BY</> clause within the aggregate call, as shown in
11213    <xref linkend="syntax-aggregates">.
11214    Alternatively, supplying the input values from a sorted subquery
11215    will usually work.  For example:
11216
11217 <screen><![CDATA[
11218 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
11219 ]]></screen>
11220
11221    But this syntax is not allowed in the SQL standard, and is
11222    not portable to other database systems.
11223   </para>
11224
11225   <para>
11226    <xref linkend="functions-aggregate-statistics-table"> shows
11227    aggregate functions typically used in statistical analysis.
11228    (These are separated out merely to avoid cluttering the listing
11229    of more-commonly-used aggregates.)  Where the description mentions
11230    <replaceable class="parameter">N</replaceable>, it means the
11231    number of input rows for which all the input expressions are non-null.
11232    In all cases, null is returned if the computation is meaningless,
11233    for example when <replaceable class="parameter">N</replaceable> is zero.
11234   </para>
11235
11236   <indexterm>
11237    <primary>statistics</primary>
11238   </indexterm>
11239   <indexterm>
11240    <primary>linear regression</primary>
11241   </indexterm>
11242
11243   <table id="functions-aggregate-statistics-table">
11244    <title>Aggregate Functions for Statistics</title>
11245
11246    <tgroup cols="4">
11247     <thead>
11248      <row>
11249       <entry>Function</entry>
11250       <entry>Argument Type</entry>
11251       <entry>Return Type</entry>
11252       <entry>Description</entry>
11253      </row>
11254     </thead>
11255
11256     <tbody>
11257
11258      <row>
11259       <entry>
11260        <indexterm>
11261         <primary>correlation</primary>
11262        </indexterm>
11263        <indexterm>
11264         <primary>corr</primary>
11265        </indexterm>
11266        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11267       </entry>
11268       <entry>
11269        <type>double precision</type>
11270       </entry>
11271       <entry>
11272        <type>double precision</type>
11273       </entry>
11274       <entry>correlation coefficient</entry>
11275      </row>
11276
11277      <row>
11278       <entry>
11279        <indexterm>
11280         <primary>covariance</primary>
11281         <secondary>population</secondary>
11282        </indexterm>
11283        <indexterm>
11284         <primary>covar_pop</primary>
11285        </indexterm>
11286        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11287       </entry>
11288       <entry>
11289        <type>double precision</type>
11290       </entry>
11291       <entry>
11292        <type>double precision</type>
11293       </entry>
11294       <entry>population covariance</entry>
11295      </row>
11296
11297      <row>
11298       <entry>
11299        <indexterm>
11300         <primary>covariance</primary>
11301         <secondary>sample</secondary>
11302        </indexterm>
11303        <indexterm>
11304         <primary>covar_samp</primary>
11305        </indexterm>
11306        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11307       </entry>
11308       <entry>
11309        <type>double precision</type>
11310       </entry>
11311       <entry>
11312        <type>double precision</type>
11313       </entry>
11314       <entry>sample covariance</entry>
11315      </row>
11316
11317      <row>
11318       <entry>
11319        <indexterm>
11320         <primary>regr_avgx</primary>
11321        </indexterm>
11322        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11323       </entry>
11324       <entry>
11325        <type>double precision</type>
11326       </entry>
11327       <entry>
11328        <type>double precision</type>
11329       </entry>
11330       <entry>average of the independent variable
11331       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
11332      </row>
11333
11334      <row>
11335       <entry>
11336        <indexterm>
11337         <primary>regr_avgy</primary>
11338        </indexterm>
11339        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11340       </entry>
11341       <entry>
11342        <type>double precision</type>
11343       </entry>
11344       <entry>
11345        <type>double precision</type>
11346       </entry>
11347       <entry>average of the dependent variable
11348       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
11349      </row>
11350
11351      <row>
11352       <entry>
11353        <indexterm>
11354         <primary>regr_count</primary>
11355        </indexterm>
11356        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11357       </entry>
11358       <entry>
11359        <type>double precision</type>
11360       </entry>
11361       <entry>
11362        <type>bigint</type>
11363       </entry>
11364       <entry>number of input rows in which both expressions are nonnull</entry>
11365      </row>
11366
11367      <row>
11368       <entry>
11369        <indexterm>
11370         <primary>regression intercept</primary>
11371        </indexterm>
11372        <indexterm>
11373         <primary>regr_intercept</primary>
11374        </indexterm>
11375        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11376       </entry>
11377       <entry>
11378        <type>double precision</type>
11379       </entry>
11380       <entry>
11381        <type>double precision</type>
11382       </entry>
11383       <entry>y-intercept of the least-squares-fit linear equation
11384       determined by the (<replaceable
11385       class="parameter">X</replaceable>, <replaceable
11386       class="parameter">Y</replaceable>) pairs</entry>
11387      </row>
11388
11389      <row>
11390       <entry>
11391        <indexterm>
11392         <primary>regr_r2</primary>
11393        </indexterm>
11394        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11395       </entry>
11396       <entry>
11397        <type>double precision</type>
11398       </entry>
11399       <entry>
11400        <type>double precision</type>
11401       </entry>
11402       <entry>square of the correlation coefficient</entry>
11403      </row>
11404
11405      <row>
11406       <entry>
11407        <indexterm>
11408         <primary>regression slope</primary>
11409        </indexterm>
11410        <indexterm>
11411         <primary>regr_slope</primary>
11412        </indexterm>
11413        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11414       </entry>
11415       <entry>
11416        <type>double precision</type>
11417       </entry>
11418       <entry>
11419        <type>double precision</type>
11420       </entry>
11421       <entry>slope of the least-squares-fit linear equation determined
11422       by the (<replaceable class="parameter">X</replaceable>,
11423       <replaceable class="parameter">Y</replaceable>) pairs</entry>
11424      </row>
11425
11426      <row>
11427       <entry>
11428        <indexterm>
11429         <primary>regr_sxx</primary>
11430        </indexterm>
11431        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11432       </entry>
11433       <entry>
11434        <type>double precision</type>
11435       </entry>
11436       <entry>
11437        <type>double precision</type>
11438       </entry>
11439       <entry><literal>sum(<replaceable
11440       class="parameter">X</replaceable>^2) - sum(<replaceable
11441       class="parameter">X</replaceable>)^2/<replaceable
11442       class="parameter">N</replaceable></literal> (<quote>sum of
11443       squares</quote> of the independent variable)</entry>
11444      </row>
11445
11446      <row>
11447       <entry>
11448        <indexterm>
11449         <primary>regr_sxy</primary>
11450        </indexterm>
11451        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11452       </entry>
11453       <entry>
11454        <type>double precision</type>
11455       </entry>
11456       <entry>
11457        <type>double precision</type>
11458       </entry>
11459       <entry><literal>sum(<replaceable
11460       class="parameter">X</replaceable>*<replaceable
11461       class="parameter">Y</replaceable>) - sum(<replaceable
11462       class="parameter">X</replaceable>) * sum(<replaceable
11463       class="parameter">Y</replaceable>)/<replaceable
11464       class="parameter">N</replaceable></literal> (<quote>sum of
11465       products</quote> of independent times dependent
11466       variable)</entry>
11467      </row>
11468
11469      <row>
11470       <entry>
11471        <indexterm>
11472         <primary>regr_syy</primary>
11473        </indexterm>
11474        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11475       </entry>
11476       <entry>
11477        <type>double precision</type>
11478       </entry>
11479       <entry>
11480        <type>double precision</type>
11481       </entry>
11482       <entry><literal>sum(<replaceable
11483       class="parameter">Y</replaceable>^2) - sum(<replaceable
11484       class="parameter">Y</replaceable>)^2/<replaceable
11485       class="parameter">N</replaceable></literal> (<quote>sum of
11486       squares</quote> of the dependent variable)</entry>
11487      </row>
11488
11489      <row>
11490       <entry>
11491        <indexterm>
11492         <primary>standard deviation</primary>
11493        </indexterm>
11494        <indexterm>
11495         <primary>stddev</primary>
11496        </indexterm>
11497        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
11498       </entry>
11499       <entry>
11500        <type>smallint</type>, <type>int</type>,
11501        <type>bigint</type>, <type>real</type>, <type>double
11502        precision</type>, or <type>numeric</type>
11503       </entry>
11504       <entry>
11505        <type>double precision</type> for floating-point arguments,
11506        otherwise <type>numeric</type>
11507       </entry>
11508       <entry>historical alias for <function>stddev_samp</function></entry>
11509      </row>
11510
11511      <row>
11512       <entry>
11513        <indexterm>
11514         <primary>standard deviation</primary>
11515         <secondary>population</secondary>
11516        </indexterm>
11517        <indexterm>
11518         <primary>stddev_pop</primary>
11519        </indexterm>
11520        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
11521       </entry>
11522       <entry>
11523        <type>smallint</type>, <type>int</type>,
11524        <type>bigint</type>, <type>real</type>, <type>double
11525        precision</type>, or <type>numeric</type>
11526       </entry>
11527       <entry>
11528        <type>double precision</type> for floating-point arguments,
11529        otherwise <type>numeric</type>
11530       </entry>
11531       <entry>population standard deviation of the input values</entry>
11532      </row>
11533
11534      <row>
11535       <entry>
11536        <indexterm>
11537         <primary>standard deviation</primary>
11538         <secondary>sample</secondary>
11539        </indexterm>
11540        <indexterm>
11541         <primary>stddev_samp</primary>
11542        </indexterm>
11543        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
11544       </entry>
11545       <entry>
11546        <type>smallint</type>, <type>int</type>,
11547        <type>bigint</type>, <type>real</type>, <type>double
11548        precision</type>, or <type>numeric</type>
11549       </entry>
11550       <entry>
11551        <type>double precision</type> for floating-point arguments,
11552        otherwise <type>numeric</type>
11553       </entry>
11554       <entry>sample standard deviation of the input values</entry>
11555      </row>
11556
11557      <row>
11558       <entry>
11559        <indexterm>
11560         <primary>variance</primary>
11561        </indexterm>
11562        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
11563       </entry>
11564       <entry>
11565        <type>smallint</type>, <type>int</type>,
11566        <type>bigint</type>, <type>real</type>, <type>double
11567        precision</type>, or <type>numeric</type>
11568       </entry>
11569       <entry>
11570        <type>double precision</type> for floating-point arguments,
11571        otherwise <type>numeric</type>
11572       </entry>
11573       <entry>historical alias for <function>var_samp</function></entry>
11574      </row>
11575
11576      <row>
11577       <entry>
11578        <indexterm>
11579         <primary>variance</primary>
11580         <secondary>population</secondary>
11581        </indexterm>
11582        <indexterm>
11583         <primary>var_pop</primary>
11584        </indexterm>
11585        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
11586       </entry>
11587       <entry>
11588        <type>smallint</type>, <type>int</type>,
11589        <type>bigint</type>, <type>real</type>, <type>double
11590        precision</type>, or <type>numeric</type>
11591       </entry>
11592       <entry>
11593        <type>double precision</type> for floating-point arguments,
11594        otherwise <type>numeric</type>
11595       </entry>
11596       <entry>population variance of the input values (square of the population standard deviation)</entry>
11597      </row>
11598
11599      <row>
11600       <entry>
11601        <indexterm>
11602         <primary>variance</primary>
11603         <secondary>sample</secondary>
11604        </indexterm>
11605        <indexterm>
11606         <primary>var_samp</primary>
11607        </indexterm>
11608        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
11609       </entry>
11610       <entry>
11611        <type>smallint</type>, <type>int</type>,
11612        <type>bigint</type>, <type>real</type>, <type>double
11613        precision</type>, or <type>numeric</type>
11614       </entry>
11615       <entry>
11616        <type>double precision</type> for floating-point arguments,
11617        otherwise <type>numeric</type>
11618       </entry>
11619       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
11620      </row>
11621     </tbody>
11622    </tgroup>
11623   </table>
11624
11625  </sect1>
11626
11627  <sect1 id="functions-window">
11628   <title>Window Functions</title>
11629
11630   <indexterm zone="functions-window">
11631    <primary>window function</primary>
11632    <secondary>built-in</secondary>
11633   </indexterm>
11634
11635   <para>
11636    <firstterm>Window functions</firstterm> provide the ability to perform
11637    calculations across sets of rows that are related to the current query
11638    row.  See <xref linkend="tutorial-window"> for an introduction to this
11639    feature.
11640   </para>
11641
11642   <para>
11643    The built-in window functions are listed in
11644    <xref linkend="functions-window-table">.  Note that these functions
11645    <emphasis>must</> be invoked using window function syntax; that is an
11646    <literal>OVER</> clause is required.
11647   </para>
11648
11649   <para>
11650    In addition to these functions, any built-in or user-defined aggregate
11651    function can be used as a window function (see
11652    <xref linkend="functions-aggregate"> for a list of the built-in aggregates).
11653    Aggregate functions act as window functions only when an <literal>OVER</>
11654    clause follows the call; otherwise they act as regular aggregates.
11655   </para>
11656
11657   <table id="functions-window-table">
11658    <title>General-Purpose Window Functions</title>
11659
11660    <tgroup cols="3">
11661     <thead>
11662      <row>
11663       <entry>Function</entry>
11664       <entry>Return Type</entry>
11665       <entry>Description</entry>
11666      </row>
11667     </thead>
11668
11669     <tbody>
11670      <row>
11671       <entry>
11672        <indexterm>
11673         <primary>row_number</primary>
11674        </indexterm>
11675        <function>row_number()</function>
11676       </entry>
11677       <entry>
11678        <type>bigint</type>
11679       </entry>
11680       <entry>number of the current row within its partition, counting from 1</entry>
11681      </row>
11682
11683      <row>
11684       <entry>
11685        <indexterm>
11686         <primary>rank</primary>
11687        </indexterm>
11688        <function>rank()</function>
11689       </entry>
11690       <entry>
11691        <type>bigint</type>
11692       </entry>
11693       <entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
11694      </row>
11695
11696      <row>
11697       <entry>
11698        <indexterm>
11699         <primary>dense_rank</primary>
11700        </indexterm>
11701        <function>dense_rank()</function>
11702       </entry>
11703       <entry>
11704        <type>bigint</type>
11705       </entry>
11706       <entry>rank of the current row without gaps; this function counts peer groups</entry>
11707      </row>
11708
11709      <row>
11710       <entry>
11711        <indexterm>
11712         <primary>percent_rank</primary>
11713        </indexterm>
11714        <function>percent_rank()</function>
11715       </entry>
11716       <entry>
11717        <type>double precision</type>
11718       </entry>
11719       <entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
11720      </row>
11721
11722      <row>
11723       <entry>
11724        <indexterm>
11725         <primary>cume_dist</primary>
11726        </indexterm>
11727        <function>cume_dist()</function>
11728       </entry>
11729       <entry>
11730        <type>double precision</type>
11731       </entry>
11732       <entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
11733      </row>
11734
11735      <row>
11736       <entry>
11737        <indexterm>
11738         <primary>ntile</primary>
11739        </indexterm>
11740        <function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</>)</function>
11741       </entry>
11742       <entry>
11743        <type>integer</type>
11744       </entry>
11745       <entry>integer ranging from 1 to the argument value, dividing the
11746        partition as equally as possible</entry>
11747      </row>
11748
11749      <row>
11750       <entry>
11751        <indexterm>
11752         <primary>lag</primary>
11753        </indexterm>
11754        <function>
11755          lag(<replaceable class="parameter">value</replaceable> <type>any</>
11756              [, <replaceable class="parameter">offset</replaceable> <type>integer</>
11757              [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
11758        </function>
11759       </entry>
11760       <entry>
11761        <type>same type as <replaceable class="parameter">value</replaceable></type>
11762       </entry>
11763       <entry>
11764        returns <replaceable class="parameter">value</replaceable> evaluated at
11765        the row that is <replaceable class="parameter">offset</replaceable>
11766        rows before the current row within the partition; if there is no such
11767        row, instead return <replaceable class="parameter">default</replaceable>.
11768        Both <replaceable class="parameter">offset</replaceable> and
11769        <replaceable class="parameter">default</replaceable> are evaluated
11770        with respect to the current row.  If omitted,
11771        <replaceable class="parameter">offset</replaceable> defaults to 1 and
11772        <replaceable class="parameter">default</replaceable> to null
11773       </entry>
11774      </row>
11775
11776      <row>
11777       <entry>
11778        <indexterm>
11779         <primary>lead</primary>
11780        </indexterm>
11781        <function>
11782          lead(<replaceable class="parameter">value</replaceable> <type>any</>
11783               [, <replaceable class="parameter">offset</replaceable> <type>integer</>
11784               [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
11785        </function>
11786       </entry>
11787       <entry>
11788        <type>same type as <replaceable class="parameter">value</replaceable></type>
11789       </entry>
11790       <entry>
11791        returns <replaceable class="parameter">value</replaceable> evaluated at
11792        the row that is <replaceable class="parameter">offset</replaceable>
11793        rows after the current row within the partition; if there is no such
11794        row, instead return <replaceable class="parameter">default</replaceable>.
11795        Both <replaceable class="parameter">offset</replaceable> and
11796        <replaceable class="parameter">default</replaceable> are evaluated
11797        with respect to the current row.  If omitted,
11798        <replaceable class="parameter">offset</replaceable> defaults to 1 and
11799        <replaceable class="parameter">default</replaceable> to null
11800       </entry>
11801      </row>
11802
11803      <row>
11804       <entry>
11805        <indexterm>
11806         <primary>first_value</primary>
11807        </indexterm>
11808        <function>first_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
11809       </entry>
11810       <entry>
11811        <type>same type as <replaceable class="parameter">value</replaceable></type>
11812       </entry>
11813       <entry>
11814        returns <replaceable class="parameter">value</replaceable> evaluated
11815        at the row that is the first row of the window frame
11816       </entry>
11817      </row>
11818
11819      <row>
11820       <entry>
11821        <indexterm>
11822         <primary>last_value</primary>
11823        </indexterm>
11824        <function>last_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
11825       </entry>
11826       <entry>
11827        <type>same type as <replaceable class="parameter">value</replaceable></type>
11828       </entry>
11829       <entry>
11830        returns <replaceable class="parameter">value</replaceable> evaluated
11831        at the row that is the last row of the window frame
11832       </entry>
11833      </row>
11834
11835      <row>
11836       <entry>
11837        <indexterm>
11838         <primary>nth_value</primary>
11839        </indexterm>
11840        <function>
11841          nth_value(<replaceable class="parameter">value</replaceable> <type>any</>, <replaceable class="parameter">nth</replaceable> <type>integer</>)
11842        </function>
11843       </entry>
11844       <entry>
11845        <type>same type as <replaceable class="parameter">value</replaceable></type>
11846       </entry>
11847       <entry>
11848        returns <replaceable class="parameter">value</replaceable> evaluated
11849        at the row that is the <replaceable class="parameter">nth</replaceable>
11850        row of the window frame (counting from 1); null if no such row
11851       </entry>
11852      </row>
11853     </tbody>
11854    </tgroup>
11855   </table>
11856
11857   <para>
11858    All of the functions listed in
11859    <xref linkend="functions-window-table"> depend on the sort ordering
11860    specified by the <literal>ORDER BY</> clause of the associated window
11861    definition.  Rows that are not distinct in the <literal>ORDER BY</>
11862    ordering are said to be <firstterm>peers</>; the four ranking functions
11863    are defined so that they give the same answer for any two peer rows.
11864   </para>
11865
11866   <para>
11867    Note that <function>first_value</>, <function>last_value</>, and
11868    <function>nth_value</> consider only the rows within the <quote>window
11869    frame</>, which by default contains the rows from the start of the
11870    partition through the last peer of the current row.  This is
11871    likely to give unhelpful results for <function>last_value</> and
11872    sometimes also <function>nth_value</>.  You can redefine the frame by
11873    adding a suitable frame specification (<literal>RANGE</> or
11874    <literal>ROWS</>) to the <literal>OVER</> clause.
11875    See <xref linkend="syntax-window-functions"> for more information
11876    about frame specifications.
11877   </para>
11878
11879   <para>
11880    When an aggregate function is used as a window function, it aggregates
11881    over the rows within the current row's window frame.
11882    An aggregate used with <literal>ORDER BY</> and the default window frame
11883    definition produces a <quote>running sum</> type of behavior, which may or
11884    may not be what's wanted.  To obtain
11885    aggregation over the whole partition, omit <literal>ORDER BY</> or use
11886    <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
11887    Other frame specifications can be used to obtain other effects.
11888   </para>
11889
11890   <note>
11891    <para>
11892     The SQL standard defines a <literal>RESPECT NULLS</> or
11893     <literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
11894     <function>first_value</>, <function>last_value</>, and
11895     <function>nth_value</>.  This is not implemented in
11896     <productname>PostgreSQL</productname>: the behavior is always the
11897     same as the standard's default, namely <literal>RESPECT NULLS</>.
11898     Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
11899     option for <function>nth_value</> is not implemented: only the
11900     default <literal>FROM FIRST</> behavior is supported.  (You can achieve
11901     the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
11902     ordering.)
11903    </para>
11904   </note>
11905
11906  </sect1>
11907
11908  <sect1 id="functions-subquery">
11909   <title>Subquery Expressions</title>
11910
11911   <indexterm>
11912    <primary>EXISTS</primary>
11913   </indexterm>
11914
11915   <indexterm>
11916    <primary>IN</primary>
11917   </indexterm>
11918
11919   <indexterm>
11920    <primary>NOT IN</primary>
11921   </indexterm>
11922
11923   <indexterm>
11924    <primary>ANY</primary>
11925   </indexterm>
11926
11927   <indexterm>
11928    <primary>ALL</primary>
11929   </indexterm>
11930
11931   <indexterm>
11932    <primary>SOME</primary>
11933   </indexterm>
11934
11935   <indexterm>
11936    <primary>subquery</primary>
11937   </indexterm>
11938
11939   <para>
11940    This section describes the <acronym>SQL</acronym>-compliant subquery
11941    expressions available in <productname>PostgreSQL</productname>.
11942    All of the expression forms documented in this section return
11943    Boolean (true/false) results.
11944   </para>
11945
11946   <sect2 id="functions-subquery-exists">
11947    <title><literal>EXISTS</literal></title>
11948
11949 <synopsis>
11950 EXISTS (<replaceable>subquery</replaceable>)
11951 </synopsis>
11952
11953   <para>
11954    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
11955    or <firstterm>subquery</firstterm>.  The
11956    subquery is evaluated to determine whether it returns any rows.
11957    If it returns at least one row, the result of <token>EXISTS</token> is
11958    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
11959    is <quote>false</>.
11960   </para>
11961
11962   <para>
11963    The subquery can refer to variables from the surrounding query,
11964    which will act as constants during any one evaluation of the subquery.
11965   </para>
11966
11967   <para>
11968    The subquery will generally only be executed long enough to determine
11969    whether at least one row is returned, not all the way to completion.
11970    It is unwise to write a subquery that has side effects (such as
11971    calling sequence functions); whether the side effects occur
11972    might be unpredictable.
11973   </para>
11974
11975   <para>
11976    Since the result depends only on whether any rows are returned,
11977    and not on the contents of those rows, the output list of the
11978    subquery is normally unimportant.  A common coding convention is
11979    to write all <literal>EXISTS</> tests in the form
11980    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
11981    this rule however, such as subqueries that use <token>INTERSECT</token>.
11982   </para>
11983
11984   <para>
11985    This simple example is like an inner join on <literal>col2</>, but
11986    it produces at most one output row for each <literal>tab1</> row,
11987    even if there are several matching <literal>tab2</> rows:
11988 <screen>
11989 SELECT col1
11990 FROM tab1
11991 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
11992 </screen>
11993   </para>
11994   </sect2>
11995
11996   <sect2 id="functions-subquery-in">
11997    <title><literal>IN</literal></title>
11998
11999 <synopsis>
12000 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
12001 </synopsis>
12002
12003   <para>
12004    The right-hand side is a parenthesized
12005    subquery, which must return exactly one column.  The left-hand expression
12006    is evaluated and compared to each row of the subquery result.
12007    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
12008    The result is <quote>false</> if no equal row is found (including the
12009    case where the subquery returns no rows).
12010   </para>
12011
12012   <para>
12013    Note that if the left-hand expression yields null, or if there are
12014    no equal right-hand values and at least one right-hand row yields
12015    null, the result of the <token>IN</token> construct will be null, not false.
12016    This is in accordance with SQL's normal rules for Boolean combinations
12017    of null values.
12018   </para>
12019
12020   <para>
12021    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
12022    be evaluated completely.
12023   </para>
12024
12025 <synopsis>
12026 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
12027 </synopsis>
12028
12029   <para>
12030    The left-hand side of this form of <token>IN</token> is a row constructor,
12031    as described in <xref linkend="sql-syntax-row-constructors">.
12032    The right-hand side is a parenthesized
12033    subquery, which must return exactly as many columns as there are
12034    expressions in the left-hand row.  The left-hand expressions are
12035    evaluated and compared row-wise to each row of the subquery result.
12036    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
12037    The result is <quote>false</> if no equal row is found (including the
12038    case where the subquery returns no rows).
12039   </para>
12040
12041   <para>
12042    As usual, null values in the rows are combined per
12043    the normal rules of SQL Boolean expressions.  Two rows are considered
12044    equal if all their corresponding members are non-null and equal; the rows
12045    are unequal if any corresponding members are non-null and unequal;
12046    otherwise the result of that row comparison is unknown (null).
12047    If all the per-row results are either unequal or null, with at least one
12048    null, then the result of <token>IN</token> is null.
12049   </para>
12050   </sect2>
12051
12052   <sect2 id="functions-subquery-notin">
12053    <title><literal>NOT IN</literal></title>
12054
12055 <synopsis>
12056 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
12057 </synopsis>
12058
12059   <para>
12060    The right-hand side is a parenthesized
12061    subquery, which must return exactly one column.  The left-hand expression
12062    is evaluated and compared to each row of the subquery result.
12063    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
12064    are found (including the case where the subquery returns no rows).
12065    The result is <quote>false</> if any equal row is found.
12066   </para>
12067
12068   <para>
12069    Note that if the left-hand expression yields null, or if there are
12070    no equal right-hand values and at least one right-hand row yields
12071    null, the result of the <token>NOT IN</token> construct will be null, not true.
12072    This is in accordance with SQL's normal rules for Boolean combinations
12073    of null values.
12074   </para>
12075
12076   <para>
12077    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
12078    be evaluated completely.
12079   </para>
12080
12081 <synopsis>
12082 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
12083 </synopsis>
12084
12085   <para>
12086    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
12087    as described in <xref linkend="sql-syntax-row-constructors">.
12088    The right-hand side is a parenthesized
12089    subquery, which must return exactly as many columns as there are
12090    expressions in the left-hand row.  The left-hand expressions are
12091    evaluated and compared row-wise to each row of the subquery result.
12092    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
12093    are found (including the case where the subquery returns no rows).
12094    The result is <quote>false</> if any equal row is found.
12095   </para>
12096
12097   <para>
12098    As usual, null values in the rows are combined per
12099    the normal rules of SQL Boolean expressions.  Two rows are considered
12100    equal if all their corresponding members are non-null and equal; the rows
12101    are unequal if any corresponding members are non-null and unequal;
12102    otherwise the result of that row comparison is unknown (null).
12103    If all the per-row results are either unequal or null, with at least one
12104    null, then the result of <token>NOT IN</token> is null.
12105   </para>
12106   </sect2>
12107
12108   <sect2 id="functions-subquery-any-some">
12109    <title><literal>ANY</literal>/<literal>SOME</literal></title>
12110
12111 <synopsis>
12112 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
12113 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
12114 </synopsis>
12115
12116   <para>
12117    The right-hand side is a parenthesized
12118    subquery, which must return exactly one column.  The left-hand expression
12119    is evaluated and compared to each row of the subquery result using the
12120    given <replaceable>operator</replaceable>, which must yield a Boolean
12121    result.
12122    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
12123    The result is <quote>false</> if no true result is found (including the
12124    case where the subquery returns no rows).
12125   </para>
12126
12127   <para>
12128    <token>SOME</token> is a synonym for <token>ANY</token>.
12129    <token>IN</token> is equivalent to <literal>= ANY</literal>.
12130   </para>
12131
12132   <para>
12133    Note that if there are no successes and at least one right-hand row yields
12134    null for the operator's result, the result of the <token>ANY</token> construct
12135    will be null, not false.
12136    This is in accordance with SQL's normal rules for Boolean combinations
12137    of null values.
12138   </para>
12139
12140   <para>
12141    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
12142    be evaluated completely.
12143   </para>
12144
12145 <synopsis>
12146 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
12147 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
12148 </synopsis>
12149
12150   <para>
12151    The left-hand side of this form of <token>ANY</token> is a row constructor,
12152    as described in <xref linkend="sql-syntax-row-constructors">.
12153    The right-hand side is a parenthesized
12154    subquery, which must return exactly as many columns as there are
12155    expressions in the left-hand row.  The left-hand expressions are
12156    evaluated and compared row-wise to each row of the subquery result,
12157    using the given <replaceable>operator</replaceable>.
12158    The result of <token>ANY</token> is <quote>true</> if the comparison
12159    returns true for any subquery row.
12160    The result is <quote>false</> if the comparison returns false for every
12161    subquery row (including the case where the subquery returns no
12162    rows).
12163    The result is NULL if the comparison does not return true for any row,
12164    and it returns NULL for at least one row.
12165   </para>
12166
12167   <para>
12168    See <xref linkend="row-wise-comparison"> for details about the meaning
12169    of a row-wise comparison.
12170   </para>
12171   </sect2>
12172
12173   <sect2 id="functions-subquery-all">
12174    <title><literal>ALL</literal></title>
12175
12176 <synopsis>
12177 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
12178 </synopsis>
12179
12180   <para>
12181    The right-hand side is a parenthesized
12182    subquery, which must return exactly one column.  The left-hand expression
12183    is evaluated and compared to each row of the subquery result using the
12184    given <replaceable>operator</replaceable>, which must yield a Boolean
12185    result.
12186    The result of <token>ALL</token> is <quote>true</> if all rows yield true
12187    (including the case where the subquery returns no rows).
12188    The result is <quote>false</> if any false result is found.
12189    The result is NULL if the comparison does not return false for any row,
12190    and it returns NULL for at least one row.
12191   </para>
12192
12193   <para>
12194    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
12195   </para>
12196
12197   <para>
12198    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
12199    be evaluated completely.
12200   </para>
12201
12202 <synopsis>
12203 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
12204 </synopsis>
12205
12206   <para>
12207    The left-hand side of this form of <token>ALL</token> is a row constructor,
12208    as described in <xref linkend="sql-syntax-row-constructors">.
12209    The right-hand side is a parenthesized
12210    subquery, which must return exactly as many columns as there are
12211    expressions in the left-hand row.  The left-hand expressions are
12212    evaluated and compared row-wise to each row of the subquery result,
12213    using the given <replaceable>operator</replaceable>.
12214    The result of <token>ALL</token> is <quote>true</> if the comparison
12215    returns true for all subquery rows (including the
12216    case where the subquery returns no rows).
12217    The result is <quote>false</> if the comparison returns false for any
12218    subquery row.
12219    The result is NULL if the comparison does not return false for any
12220    subquery row, and it returns NULL for at least one row.
12221   </para>
12222
12223   <para>
12224    See <xref linkend="row-wise-comparison"> for details about the meaning
12225    of a row-wise comparison.
12226   </para>
12227   </sect2>
12228
12229   <sect2>
12230    <title>Row-wise Comparison</title>
12231
12232    <indexterm zone="functions-subquery">
12233     <primary>comparison</primary>
12234     <secondary>subquery result row</secondary>
12235    </indexterm>
12236
12237 <synopsis>
12238 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
12239 </synopsis>
12240
12241   <para>
12242    The left-hand side is a row constructor,
12243    as described in <xref linkend="sql-syntax-row-constructors">.
12244    The right-hand side is a parenthesized subquery, which must return exactly
12245    as many columns as there are expressions in the left-hand row. Furthermore,
12246    the subquery cannot return more than one row.  (If it returns zero rows,
12247    the result is taken to be null.)  The left-hand side is evaluated and
12248    compared row-wise to the single subquery result row.
12249   </para>
12250
12251   <para>
12252    See <xref linkend="row-wise-comparison"> for details about the meaning
12253    of a row-wise comparison.
12254   </para>
12255   </sect2>
12256  </sect1>
12257
12258
12259  <sect1 id="functions-comparisons">
12260   <title>Row and Array Comparisons</title>
12261
12262   <indexterm>
12263    <primary>IN</primary>
12264   </indexterm>
12265
12266   <indexterm>
12267    <primary>NOT IN</primary>
12268   </indexterm>
12269
12270   <indexterm>
12271    <primary>ANY</primary>
12272   </indexterm>
12273
12274   <indexterm>
12275    <primary>ALL</primary>
12276   </indexterm>
12277
12278   <indexterm>
12279    <primary>SOME</primary>
12280   </indexterm>
12281
12282   <indexterm>
12283    <primary>row-wise comparison</primary>
12284   </indexterm>
12285
12286   <indexterm>
12287    <primary>comparison</primary>
12288    <secondary>row-wise</secondary>
12289   </indexterm>
12290
12291   <indexterm>
12292    <primary>IS DISTINCT FROM</primary>
12293   </indexterm>
12294
12295   <indexterm>
12296    <primary>IS NOT DISTINCT FROM</primary>
12297   </indexterm>
12298
12299   <para>
12300    This section describes several specialized constructs for making
12301    multiple comparisons between groups of values.  These forms are
12302    syntactically related to the subquery forms of the previous section,
12303    but do not involve subqueries.
12304    The forms involving array subexpressions are
12305    <productname>PostgreSQL</productname> extensions; the rest are
12306    <acronym>SQL</acronym>-compliant.
12307    All of the expression forms documented in this section return
12308    Boolean (true/false) results.
12309   </para>
12310
12311   <sect2>
12312    <title><literal>IN</literal></title>
12313
12314 <synopsis>
12315 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
12316 </synopsis>
12317
12318   <para>
12319    The right-hand side is a parenthesized list
12320    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
12321    result is equal to any of the right-hand expressions.  This is a shorthand
12322    notation for
12323
12324 <synopsis>
12325 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
12326 OR
12327 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
12328 OR
12329 ...
12330 </synopsis>
12331   </para>
12332
12333   <para>
12334    Note that if the left-hand expression yields null, or if there are
12335    no equal right-hand values and at least one right-hand expression yields
12336    null, the result of the <token>IN</token> construct will be null, not false.
12337    This is in accordance with SQL's normal rules for Boolean combinations
12338    of null values.
12339   </para>
12340   </sect2>
12341
12342   <sect2>
12343    <title><literal>NOT IN</literal></title>
12344
12345 <synopsis>
12346 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
12347 </synopsis>
12348
12349   <para>
12350    The right-hand side is a parenthesized list
12351    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
12352    result is unequal to all of the right-hand expressions.  This is a shorthand
12353    notation for
12354
12355 <synopsis>
12356 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
12357 AND
12358 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
12359 AND
12360 ...
12361 </synopsis>
12362   </para>
12363
12364   <para>
12365    Note that if the left-hand expression yields null, or if there are
12366    no equal right-hand values and at least one right-hand expression yields
12367    null, the result of the <token>NOT IN</token> construct will be null, not true
12368    as one might naively expect.
12369    This is in accordance with SQL's normal rules for Boolean combinations
12370    of null values.
12371   </para>
12372
12373   <tip>
12374   <para>
12375    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
12376    cases.  However, null values are much more likely to trip up the novice when
12377    working with <token>NOT IN</token> than when working with <token>IN</token>.
12378    It is best to express your condition positively if possible.
12379   </para>
12380   </tip>
12381   </sect2>
12382
12383   <sect2>
12384    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
12385
12386 <synopsis>
12387 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
12388 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
12389 </synopsis>
12390
12391   <para>
12392    The right-hand side is a parenthesized expression, which must yield an
12393    array value.
12394    The left-hand expression
12395    is evaluated and compared to each element of the array using the
12396    given <replaceable>operator</replaceable>, which must yield a Boolean
12397    result.
12398    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
12399    The result is <quote>false</> if no true result is found (including the
12400    case where the array has zero elements).
12401   </para>
12402
12403   <para>
12404    If the array expression yields a null array, the result of
12405    <token>ANY</token> will be null.  If the left-hand expression yields null,
12406    the result of <token>ANY</token> is ordinarily null (though a non-strict
12407    comparison operator could possibly yield a different result).
12408    Also, if the right-hand array contains any null elements and no true
12409    comparison result is obtained, the result of <token>ANY</token>
12410    will be null, not false (again, assuming a strict comparison operator).
12411    This is in accordance with SQL's normal rules for Boolean combinations
12412    of null values.
12413   </para>
12414
12415   <para>
12416    <token>SOME</token> is a synonym for <token>ANY</token>.
12417   </para>
12418   </sect2>
12419
12420   <sect2>
12421    <title><literal>ALL</literal> (array)</title>
12422
12423 <synopsis>
12424 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
12425 </synopsis>
12426
12427   <para>
12428    The right-hand side is a parenthesized expression, which must yield an
12429    array value.
12430    The left-hand expression
12431    is evaluated and compared to each element of the array using the
12432    given <replaceable>operator</replaceable>, which must yield a Boolean
12433    result.
12434    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
12435    (including the case where the array has zero elements).
12436    The result is <quote>false</> if any false result is found.
12437   </para>
12438
12439   <para>
12440    If the array expression yields a null array, the result of
12441    <token>ALL</token> will be null.  If the left-hand expression yields null,
12442    the result of <token>ALL</token> is ordinarily null (though a non-strict
12443    comparison operator could possibly yield a different result).
12444    Also, if the right-hand array contains any null elements and no false
12445    comparison result is obtained, the result of <token>ALL</token>
12446    will be null, not true (again, assuming a strict comparison operator).
12447    This is in accordance with SQL's normal rules for Boolean combinations
12448    of null values.
12449   </para>
12450   </sect2>
12451
12452   <sect2 id="row-wise-comparison">
12453    <title>Row-wise Comparison</title>
12454
12455 <synopsis>
12456 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
12457 </synopsis>
12458
12459   <para>
12460    Each side is a row constructor,
12461    as described in <xref linkend="sql-syntax-row-constructors">.
12462    The two row values must have the same number of fields.
12463    Each side is evaluated and they are compared row-wise.  Row comparisons
12464    are allowed when the <replaceable>operator</replaceable> is
12465    <literal>=</>,
12466    <literal>&lt;&gt;</>,
12467    <literal>&lt;</>,
12468    <literal>&lt;=</>,
12469    <literal>&gt;</> or
12470    <literal>&gt;=</>,
12471    or has semantics similar to one of these.  (To be specific, an operator
12472    can be a row comparison operator if it is a member of a B-tree operator
12473    class, or is the negator of the <literal>=</> member of a B-tree operator
12474    class.)
12475   </para>
12476
12477   <para>
12478    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
12479    from the others.  Two rows are considered
12480    equal if all their corresponding members are non-null and equal; the rows
12481    are unequal if any corresponding members are non-null and unequal;
12482    otherwise the result of the row comparison is unknown (null).
12483   </para>
12484
12485   <para>
12486    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
12487    <literal>&gt;=</> cases, the row elements are compared left-to-right,
12488    stopping as soon as an unequal or null pair of elements is found.
12489    If either of this pair of elements is null, the result of the
12490    row comparison is unknown (null); otherwise comparison of this pair
12491    of elements determines the result.  For example,
12492    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
12493    yields true, not null, because the third pair of elements are not
12494    considered.
12495   </para>
12496
12497   <note>
12498    <para>
12499     Prior to <productname>PostgreSQL</productname> 8.2, the
12500     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
12501     cases were not handled per SQL specification.  A comparison like
12502     <literal>ROW(a,b) &lt; ROW(c,d)</>
12503     was implemented as
12504     <literal>a &lt; c AND b &lt; d</>
12505     whereas the correct behavior is equivalent to
12506     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
12507    </para>
12508   </note>
12509
12510 <synopsis>
12511 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
12512 </synopsis>
12513
12514   <para>
12515    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
12516    but it does not yield null for null inputs.  Instead, any null value is
12517    considered unequal to (distinct from) any non-null value, and any two
12518    nulls are considered equal (not distinct).  Thus the result will
12519    either be true or false, never null.
12520   </para>
12521
12522 <synopsis>
12523 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
12524 </synopsis>
12525
12526   <para>
12527    This construct is similar to a <literal>=</literal> row comparison,
12528    but it does not yield null for null inputs.  Instead, any null value is
12529    considered unequal to (distinct from) any non-null value, and any two
12530    nulls are considered equal (not distinct).  Thus the result will always
12531    be either true or false, never null.
12532   </para>
12533
12534   <note>
12535    <para>
12536     The SQL specification requires row-wise comparison to return NULL if the
12537     result depends on comparing two NULL values or a NULL and a non-NULL.
12538     <productname>PostgreSQL</productname> does this only when comparing the
12539     results of two row constructors or comparing a row constructor to the
12540     output of a subquery (as in <xref linkend="functions-subquery">).
12541     In other contexts where two composite-type values are compared, two
12542     NULL field values are considered equal, and a NULL is considered larger
12543     than a non-NULL.  This is necessary in order to have consistent sorting
12544     and indexing behavior for composite types.
12545    </para>
12546   </note>
12547
12548   </sect2>
12549  </sect1>
12550
12551  <sect1 id="functions-srf">
12552   <title>Set Returning Functions</title>
12553
12554   <indexterm zone="functions-srf">
12555    <primary>set returning functions</primary>
12556    <secondary>functions</secondary>
12557   </indexterm>
12558
12559   <indexterm>
12560    <primary>generate_series</primary>
12561   </indexterm>
12562
12563   <para>
12564    This section describes functions that possibly return more than one row.
12565    The most widely used functions in this class are series generating
12566    functions, as detailed in <xref linkend="functions-srf-series"> and
12567    <xref linkend="functions-srf-subscripts">.  Other, more specialized
12568    set-returning functions are described elsewhere in this manual.
12569   </para>
12570
12571   <table id="functions-srf-series">
12572    <title>Series Generating Functions</title>
12573    <tgroup cols="4">
12574     <thead>
12575      <row>
12576       <entry>Function</entry>
12577       <entry>Argument Type</entry>
12578       <entry>Return Type</entry>
12579       <entry>Description</entry>
12580      </row>
12581     </thead>
12582
12583     <tbody>
12584      <row>
12585       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>)</function></literal></entry>
12586       <entry><type>int</type> or <type>bigint</type></entry>
12587       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
12588       <entry>
12589        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
12590        with a step size of one
12591       </entry>
12592      </row>
12593
12594      <row>
12595       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</function></literal></entry>
12596       <entry><type>int</type> or <type>bigint</type></entry>
12597       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
12598       <entry>
12599        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
12600        with a step size of <parameter>step</parameter>
12601       </entry>
12602      </row>
12603
12604      <row>
12605       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</function></literal></entry>
12606       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
12607       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
12608       <entry>
12609        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
12610        with a step size of <parameter>step</parameter>
12611       </entry>
12612      </row>
12613
12614     </tbody>
12615    </tgroup>
12616   </table>
12617
12618   <para>
12619    When <parameter>step</parameter> is positive, zero rows are returned if
12620    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
12621    Conversely, when <parameter>step</parameter> is negative, zero rows are
12622    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
12623    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
12624    for <parameter>step</parameter> to be zero. Some examples follow:
12625 <programlisting>
12626 SELECT * FROM generate_series(2,4);
12627  generate_series
12628 -----------------
12629                2
12630                3
12631                4
12632 (3 rows)
12633
12634 SELECT * FROM generate_series(5,1,-2);
12635  generate_series
12636 -----------------
12637                5
12638                3
12639                1
12640 (3 rows)
12641
12642 SELECT * FROM generate_series(4,3);
12643  generate_series
12644 -----------------
12645 (0 rows)
12646
12647 -- this example relies on the date-plus-integer operator
12648 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
12649    dates
12650 ------------
12651  2004-02-05
12652  2004-02-12
12653  2004-02-19
12654 (3 rows)
12655
12656 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
12657                               '2008-03-04 12:00', '10 hours');
12658    generate_series   
12659 ---------------------
12660  2008-03-01 00:00:00
12661  2008-03-01 10:00:00
12662  2008-03-01 20:00:00
12663  2008-03-02 06:00:00
12664  2008-03-02 16:00:00
12665  2008-03-03 02:00:00
12666  2008-03-03 12:00:00
12667  2008-03-03 22:00:00
12668  2008-03-04 08:00:00
12669 (9 rows)
12670 </programlisting>
12671   </para>
12672
12673   <table id="functions-srf-subscripts">
12674    <title>Subscript Generating Functions</title>
12675    <tgroup cols="3">
12676     <thead>
12677      <row>
12678       <entry>Function</entry>
12679       <entry>Return Type</entry>
12680       <entry>Description</entry>
12681      </row>
12682     </thead>
12683
12684     <tbody>
12685      <row>
12686       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</function></literal></entry>
12687       <entry><type>setof int</type></entry>
12688       <entry>
12689        Generate a series comprising the given array's subscripts.
12690       </entry>
12691      </row>
12692
12693      <row>
12694       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</function></literal></entry>
12695       <entry><type>setof int</type></entry>
12696       <entry>
12697        Generate a series comprising the given array's subscripts. When
12698        <parameter>reverse</parameter> is true, the series is returned in
12699        reverse order.
12700       </entry>
12701      </row>
12702
12703     </tbody>
12704    </tgroup>
12705   </table>
12706
12707   <indexterm>
12708    <primary>generate_subscripts</primary>
12709   </indexterm>
12710
12711   <para>
12712    <function>generate_subscripts</> is a convenience function that generates
12713    the set of valid subscripts for the specified dimension of the given
12714    array.
12715    Zero rows are returned for arrays that do not have the requested dimension,
12716    or for NULL arrays (but valid subscripts are returned for NULL array
12717    elements).  Some examples follow:
12718 <programlisting>
12719 -- basic usage
12720 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
12721  s 
12722 ---
12723  1
12724  2
12725  3
12726  4
12727 (4 rows)
12728
12729 -- presenting an array, the subscript and the subscripted
12730 -- value requires a subquery
12731 SELECT * FROM arrays;
12732          a          
12733 --------------------
12734  {-1,-2}
12735  {100,200,300}
12736 (2 rows)
12737
12738 SELECT a AS array, s AS subscript, a[s] AS value
12739 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
12740      array     | subscript | value
12741 ---------------+-----------+-------
12742  {-1,-2}       |         1 |    -1
12743  {-1,-2}       |         2 |    -2
12744  {100,200,300} |         1 |   100
12745  {100,200,300} |         2 |   200
12746  {100,200,300} |         3 |   300
12747 (5 rows)
12748
12749 -- unnest a 2D array
12750 CREATE OR REPLACE FUNCTION unnest2(anyarray)
12751 RETURNS SETOF anyelement AS $$
12752 select $1[i][j]
12753    from generate_subscripts($1,1) g1(i),
12754         generate_subscripts($1,2) g2(j);
12755 $$ LANGUAGE sql IMMUTABLE;
12756 CREATE FUNCTION
12757 postgres=# SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
12758  unnest2 
12759 ---------
12760        1
12761        2
12762        3
12763        4
12764 (4 rows)
12765 </programlisting>
12766   </para>
12767
12768  </sect1>
12769
12770  <sect1 id="functions-info">
12771   <title>System Information Functions</title>
12772
12773   <para>
12774    <xref linkend="functions-info-session-table"> shows several
12775    functions that extract session and system information.
12776   </para>
12777
12778   <para>
12779    In addition to the functions listed in this section, there are a number of
12780    functions related to the statistics system that also provide system
12781    information. See <xref linkend="monitoring-stats-views"> for more
12782    information.
12783   </para>
12784
12785    <table id="functions-info-session-table">
12786     <title>Session Information Functions</title>
12787     <tgroup cols="3">
12788      <thead>
12789       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12790      </thead>
12791
12792      <tbody>
12793       <row>
12794        <entry><literal><function>current_catalog</function></literal></entry>
12795        <entry><type>name</type></entry>
12796        <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
12797       </row>
12798
12799       <row>
12800        <entry><literal><function>current_database()</function></literal></entry>
12801        <entry><type>name</type></entry>
12802        <entry>name of current database</entry>
12803       </row>
12804
12805       <row>
12806        <entry><literal><function>current_query()</function></literal></entry>
12807        <entry><type>text</type></entry>
12808        <entry>text of the currently executing query, as submitted
12809        by the client (might contain more than one statement)</entry>
12810       </row>
12811
12812       <row>
12813        <entry><literal><function>current_schema</function>[()]</literal></entry>
12814        <entry><type>name</type></entry>
12815        <entry>name of current schema</entry>
12816       </row>
12817
12818       <row>
12819        <entry><literal><function>current_schemas(<type>boolean</type>)</function></literal></entry>
12820        <entry><type>name[]</type></entry>
12821        <entry>names of schemas in search path, optionally including implicit schemas</entry>
12822       </row>
12823
12824       <row>
12825        <entry><literal><function>current_user</function></literal></entry>
12826        <entry><type>name</type></entry>
12827        <entry>user name of current execution context</entry>
12828       </row>
12829
12830       <row>
12831        <entry><literal><function>inet_client_addr()</function></literal></entry>
12832        <entry><type>inet</type></entry>
12833        <entry>address of the remote connection</entry>
12834       </row>
12835
12836       <row>
12837        <entry><literal><function>inet_client_port()</function></literal></entry>
12838        <entry><type>int</type></entry>
12839        <entry>port of the remote connection</entry>
12840       </row>
12841
12842       <row>
12843        <entry><literal><function>inet_server_addr()</function></literal></entry>
12844        <entry><type>inet</type></entry>
12845        <entry>address of the local connection</entry>
12846       </row>
12847
12848       <row>
12849        <entry><literal><function>inet_server_port()</function></literal></entry>
12850        <entry><type>int</type></entry>
12851        <entry>port of the local connection</entry>
12852       </row>
12853
12854       <row>
12855        <!-- See also the entry for this in monitoring.sgml -->
12856        <entry><literal><function>pg_backend_pid()</function></literal></entry>
12857        <entry><type>int</type></entry>
12858        <entry>
12859         Process ID of the server process attached to the current session
12860        </entry>
12861       </row>
12862
12863       <row>
12864        <entry><literal><function>pg_conf_load_time()</function></literal></entry>
12865        <entry><type>timestamp with time zone</type></entry>
12866        <entry>configuration load time</entry>
12867       </row>
12868
12869       <row>
12870        <entry><literal><function>pg_is_other_temp_schema(<type>oid</type>)</function></literal></entry>
12871        <entry><type>boolean</type></entry>
12872        <entry>is schema another session's temporary schema?</entry>
12873       </row>
12874
12875       <row>
12876        <entry><literal><function>pg_listening_channels()</function></literal></entry>
12877        <entry><type>setof text</type></entry>
12878        <entry>channel names that the session is currently listening on</entry>
12879       </row>
12880
12881       <row>
12882        <entry><literal><function>pg_my_temp_schema()</function></literal></entry>
12883        <entry><type>oid</type></entry>
12884        <entry>OID of session's temporary schema, or 0 if none</entry>
12885       </row>
12886
12887       <row>
12888        <entry><literal><function>pg_postmaster_start_time()</function></literal></entry>
12889        <entry><type>timestamp with time zone</type></entry>
12890        <entry>server start time</entry>
12891       </row>
12892
12893       <row>
12894        <entry><literal><function>pg_trigger_depth()</function></literal></entry>
12895        <entry><type>int</type></entry>
12896        <entry>current nesting level of <productname>PostgreSQL</> triggers
12897        (0 if not called, directly or indirectly, from inside a trigger)</entry>
12898       </row>
12899
12900       <row>
12901        <entry><literal><function>session_user</function></literal></entry>
12902        <entry><type>name</type></entry>
12903        <entry>session user name</entry>
12904       </row>
12905
12906       <row>
12907        <entry><literal><function>user</function></literal></entry>
12908        <entry><type>name</type></entry>
12909        <entry>equivalent to <function>current_user</function></entry>
12910       </row>
12911
12912       <row>
12913        <entry><literal><function>version()</function></literal></entry>
12914        <entry><type>text</type></entry>
12915        <entry><productname>PostgreSQL</> version information</entry>
12916       </row>
12917      </tbody>
12918     </tgroup>
12919    </table>
12920
12921    <note>
12922     <para>
12923      <function>current_catalog</function>, <function>current_schema</function>,
12924      <function>current_user</function>, <function>session_user</function>,
12925      and <function>user</function> have special syntactic status
12926      in <acronym>SQL</acronym>: they must be called without trailing
12927      parentheses.  (In PostgreSQL, parentheses can optionally be used with
12928      <function>current_schema</function>, but not with the others.)
12929     </para>
12930    </note>
12931
12932    <indexterm>
12933     <primary>current_catalog</primary>
12934    </indexterm>
12935
12936    <indexterm>
12937     <primary>current_database</primary>
12938    </indexterm>
12939
12940    <indexterm>
12941     <primary>current_query</primary>
12942    </indexterm>
12943
12944    <indexterm>
12945     <primary>current_schema</primary>
12946    </indexterm>
12947
12948    <indexterm>
12949     <primary>current_schemas</primary>
12950    </indexterm>
12951
12952    <indexterm>
12953     <primary>current_user</primary>
12954    </indexterm>
12955
12956    <indexterm>
12957     <primary>pg_backend_pid</primary>
12958    </indexterm>
12959
12960    <indexterm>
12961     <primary>schema</primary>
12962     <secondary>current</secondary>
12963    </indexterm>
12964
12965    <indexterm>
12966     <primary>search path</primary>
12967     <secondary>current</secondary>
12968    </indexterm>
12969
12970    <indexterm>
12971     <primary>session_user</primary>
12972    </indexterm>
12973
12974    <indexterm>
12975     <primary>user</primary>
12976     <secondary>current</secondary>
12977    </indexterm>
12978
12979    <indexterm>
12980     <primary>user</primary>
12981    </indexterm>
12982
12983    <para>
12984     The <function>session_user</function> is normally the user who initiated
12985     the current database connection; but superusers can change this setting
12986     with <xref linkend="sql-set-session-authorization">.
12987     The <function>current_user</function> is the user identifier
12988     that is applicable for permission checking. Normally it is equal
12989     to the session user, but it can be changed with
12990     <xref linkend="sql-set-role">.
12991     It also changes during the execution of
12992     functions with the attribute <literal>SECURITY DEFINER</literal>.
12993     In Unix parlance, the session user is the <quote>real user</quote> and
12994     the current user is the <quote>effective user</quote>.
12995    </para>
12996
12997    <para>
12998     <function>current_schema</function> returns the name of the schema that is
12999     first in the search path (or a null value if the search path is
13000     empty).  This is the schema that will be used for any tables or
13001     other named objects that are created without specifying a target schema.
13002     <function>current_schemas(boolean)</function> returns an array of the names of all
13003     schemas presently in the search path.  The Boolean option determines whether or not
13004     implicitly included system schemas such as <literal>pg_catalog</> are included in the
13005     returned search path.
13006    </para>
13007
13008    <note>
13009     <para>
13010      The search path can be altered at run time.  The command is:
13011 <programlisting>
13012 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
13013 </programlisting>
13014     </para>
13015    </note>
13016
13017    <indexterm>
13018     <primary>pg_listening_channels</primary>
13019    </indexterm>
13020
13021    <para>
13022     <function>pg_listening_channels</function> returns a set of names of
13023     channels that the current session is listening to.  See <xref
13024     linkend="sql-listen"> for more information.
13025    </para>
13026
13027    <indexterm>
13028     <primary>inet_client_addr</primary>
13029    </indexterm>
13030
13031    <indexterm>
13032     <primary>inet_client_port</primary>
13033    </indexterm>
13034
13035    <indexterm>
13036     <primary>inet_server_addr</primary>
13037    </indexterm>
13038
13039    <indexterm>
13040     <primary>inet_server_port</primary>
13041    </indexterm>
13042
13043    <para>
13044      <function>inet_client_addr</function> returns the IP address of the
13045      current client, and <function>inet_client_port</function> returns the
13046      port number.
13047      <function>inet_server_addr</function> returns the IP address on which
13048      the server accepted the current connection, and
13049      <function>inet_server_port</function> returns the port number.
13050      All these functions return NULL if the current connection is via a
13051      Unix-domain socket.
13052    </para>
13053
13054    <indexterm>
13055     <primary>pg_my_temp_schema</primary>
13056    </indexterm>
13057
13058    <indexterm>
13059     <primary>pg_is_other_temp_schema</primary>
13060    </indexterm>
13061
13062    <para>
13063     <function>pg_my_temp_schema</function> returns the OID of the current
13064     session's temporary schema, or zero if it has none (because it has not
13065     created any temporary tables).
13066     <function>pg_is_other_temp_schema</function> returns true if the
13067     given OID is the OID of another session's temporary schema.
13068     (This can be useful, for example, to exclude other sessions' temporary
13069     tables from a catalog display.)
13070    </para>
13071
13072    <indexterm>
13073     <primary>pg_postmaster_start_time</primary>
13074    </indexterm>
13075
13076    <para>
13077     <function>pg_postmaster_start_time</function> returns the
13078     <type>timestamp with time zone</type> when the
13079     server started.
13080    </para>
13081
13082    <indexterm>
13083     <primary>pg_conf_load_time</primary>
13084    </indexterm>
13085
13086    <para>
13087     <function>pg_conf_load_time</function> returns the
13088     <type>timestamp with time zone</type> when the
13089     server configuration files were last loaded.
13090     (If the current session was alive at the time, this will be the time
13091     when the session itself re-read the configuration files, so the
13092     reading will vary a little in different sessions.  Otherwise it is
13093     the time when the postmaster process re-read the configuration files.)
13094    </para>
13095
13096    <indexterm>
13097     <primary>version</primary>
13098    </indexterm>
13099
13100    <para>
13101     <function>version</function> returns a string describing the
13102     <productname>PostgreSQL</productname> server's version.
13103    </para>
13104
13105   <indexterm>
13106    <primary>privilege</primary>
13107    <secondary>querying</secondary>
13108   </indexterm>
13109
13110   <para>
13111    <xref linkend="functions-info-access-table"> lists functions that
13112    allow the user to query object access privileges programmatically.
13113    See <xref linkend="ddl-priv"> for more information about
13114    privileges.
13115   </para>
13116
13117    <table id="functions-info-access-table">
13118     <title>Access Privilege Inquiry Functions</title>
13119     <tgroup cols="3">
13120      <thead>
13121       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13122      </thead>
13123
13124      <tbody>
13125       <row>
13126        <entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
13127                                   <parameter>table</parameter>,
13128                                   <parameter>privilege</parameter>)</literal>
13129        </entry>
13130        <entry><type>boolean</type></entry>
13131        <entry>does user have privilege for any column of table</entry>
13132       </row>
13133       <row>
13134        <entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
13135                                   <parameter>privilege</parameter>)</literal>
13136        </entry>
13137        <entry><type>boolean</type></entry>
13138        <entry>does current user have privilege for any column of table</entry>
13139       </row>
13140       <row>
13141        <entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
13142                                   <parameter>table</parameter>,
13143                                   <parameter>column</parameter>,
13144                                   <parameter>privilege</parameter>)</literal>
13145        </entry>
13146        <entry><type>boolean</type></entry>
13147        <entry>does user have privilege for column</entry>
13148       </row>
13149       <row>
13150        <entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
13151                                   <parameter>column</parameter>,
13152                                   <parameter>privilege</parameter>)</literal>
13153        </entry>
13154        <entry><type>boolean</type></entry>
13155        <entry>does current user have privilege for column</entry>
13156       </row>
13157       <row>
13158        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
13159                                   <parameter>database</parameter>,
13160                                   <parameter>privilege</parameter>)</literal>
13161        </entry>
13162        <entry><type>boolean</type></entry>
13163        <entry>does user have privilege for database</entry>
13164       </row>
13165       <row>
13166        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
13167                                   <parameter>privilege</parameter>)</literal>
13168        </entry>
13169        <entry><type>boolean</type></entry>
13170        <entry>does current user have privilege for database</entry>
13171       </row>
13172       <row>
13173        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
13174                                   <parameter>fdw</parameter>,
13175                                   <parameter>privilege</parameter>)</literal>
13176        </entry>
13177        <entry><type>boolean</type></entry>
13178        <entry>does user have privilege for foreign-data wrapper</entry>
13179       </row>
13180       <row>
13181        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
13182                                   <parameter>privilege</parameter>)</literal>
13183        </entry>
13184        <entry><type>boolean</type></entry>
13185        <entry>does current user have privilege for foreign-data wrapper</entry>
13186       </row>
13187       <row>
13188        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
13189                                   <parameter>function</parameter>,
13190                                   <parameter>privilege</parameter>)</literal>
13191        </entry>
13192        <entry><type>boolean</type></entry>
13193        <entry>does user have privilege for function</entry>
13194       </row>
13195       <row>
13196        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
13197                                   <parameter>privilege</parameter>)</literal>
13198        </entry>
13199        <entry><type>boolean</type></entry>
13200        <entry>does current user have privilege for function</entry>
13201       </row>
13202       <row>
13203        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
13204                                   <parameter>language</parameter>,
13205                                   <parameter>privilege</parameter>)</literal>
13206        </entry>
13207        <entry><type>boolean</type></entry>
13208        <entry>does user have privilege for language</entry>
13209       </row>
13210       <row>
13211        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
13212                                   <parameter>privilege</parameter>)</literal>
13213        </entry>
13214        <entry><type>boolean</type></entry>
13215        <entry>does current user have privilege for language</entry>
13216       </row>
13217       <row>
13218        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
13219                                   <parameter>schema</parameter>,
13220                                   <parameter>privilege</parameter>)</literal>
13221        </entry>
13222        <entry><type>boolean</type></entry>
13223        <entry>does user have privilege for schema</entry>
13224       </row>
13225       <row>
13226        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
13227                                   <parameter>privilege</parameter>)</literal>
13228        </entry>
13229        <entry><type>boolean</type></entry>
13230        <entry>does current user have privilege for schema</entry>
13231       </row>
13232       <row>
13233        <entry><literal><function>has_sequence_privilege</function>(<parameter>user</parameter>,
13234                                   <parameter>sequence</parameter>,
13235                                   <parameter>privilege</parameter>)</literal>
13236        </entry>
13237        <entry><type>boolean</type></entry>
13238        <entry>does user have privilege for sequence</entry>
13239       </row>
13240       <row>
13241        <entry><literal><function>has_sequence_privilege</function>(<parameter>sequence</parameter>,
13242                                   <parameter>privilege</parameter>)</literal>
13243        </entry>
13244        <entry><type>boolean</type></entry>
13245        <entry>does current user have privilege for sequence</entry>
13246       </row>
13247       <row>
13248        <entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
13249                                   <parameter>server</parameter>,
13250                                   <parameter>privilege</parameter>)</literal>
13251        </entry>
13252        <entry><type>boolean</type></entry>
13253        <entry>does user have privilege for foreign server</entry>
13254       </row>
13255       <row>
13256        <entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
13257                                   <parameter>privilege</parameter>)</literal>
13258        </entry>
13259        <entry><type>boolean</type></entry>
13260        <entry>does current user have privilege for foreign server</entry>
13261       </row>
13262       <row>
13263        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
13264                                   <parameter>table</parameter>,
13265                                   <parameter>privilege</parameter>)</literal>
13266        </entry>
13267        <entry><type>boolean</type></entry>
13268        <entry>does user have privilege for table</entry>
13269       </row>
13270       <row>
13271        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
13272                                   <parameter>privilege</parameter>)</literal>
13273        </entry>
13274        <entry><type>boolean</type></entry>
13275        <entry>does current user have privilege for table</entry>
13276       </row>
13277       <row>
13278        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
13279                                   <parameter>tablespace</parameter>,
13280                                   <parameter>privilege</parameter>)</literal>
13281        </entry>
13282        <entry><type>boolean</type></entry>
13283        <entry>does user have privilege for tablespace</entry>
13284       </row>
13285       <row>
13286        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
13287                                   <parameter>privilege</parameter>)</literal>
13288        </entry>
13289        <entry><type>boolean</type></entry>
13290        <entry>does current user have privilege for tablespace</entry>
13291       </row>
13292       <row>
13293        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
13294                                   <parameter>role</parameter>,
13295                                   <parameter>privilege</parameter>)</literal>
13296        </entry>
13297        <entry><type>boolean</type></entry>
13298        <entry>does user have privilege for role</entry>
13299       </row>
13300       <row>
13301        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
13302                                   <parameter>privilege</parameter>)</literal>
13303        </entry>
13304        <entry><type>boolean</type></entry>
13305        <entry>does current user have privilege for role</entry>
13306       </row>
13307      </tbody>
13308     </tgroup>
13309    </table>
13310
13311    <indexterm>
13312     <primary>has_any_column_privilege</primary>
13313    </indexterm>
13314    <indexterm>
13315     <primary>has_column_privilege</primary>
13316    </indexterm>
13317    <indexterm>
13318     <primary>has_database_privilege</primary>
13319    </indexterm>
13320    <indexterm>
13321     <primary>has_function_privilege</primary>
13322    </indexterm>
13323    <indexterm>
13324     <primary>has_foreign_data_wrapper_privilege</primary>
13325    </indexterm>
13326    <indexterm>
13327     <primary>has_language_privilege</primary>
13328    </indexterm>
13329    <indexterm>
13330     <primary>has_schema_privilege</primary>
13331    </indexterm>
13332    <indexterm>
13333     <primary>has_server_privilege</primary>
13334    </indexterm>
13335    <indexterm>
13336     <primary>has_sequence_privilege</primary>
13337    </indexterm>
13338    <indexterm>
13339     <primary>has_table_privilege</primary>
13340    </indexterm>
13341    <indexterm>
13342     <primary>has_tablespace_privilege</primary>
13343    </indexterm>
13344    <indexterm>
13345     <primary>pg_has_role</primary>
13346    </indexterm>
13347
13348    <para>
13349     <function>has_table_privilege</function> checks whether a user
13350     can access a table in a particular way.  The user can be
13351     specified by name, by OID (<literal>pg_authid.oid</literal>),
13352     <literal>public</> to indicate the PUBLIC pseudo-role, or if the argument is
13353     omitted
13354     <function>current_user</function> is assumed.  The table can be specified
13355     by name or by OID.  (Thus, there are actually six variants of
13356     <function>has_table_privilege</function>, which can be distinguished by
13357     the number and types of their arguments.)  When specifying by name,
13358     the name can be schema-qualified if necessary.
13359     The desired access privilege type
13360     is specified by a text string, which must evaluate to one of the
13361     values <literal>SELECT</literal>, <literal>INSERT</literal>,
13362     <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
13363     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.  Optionally,
13364     <literal>WITH GRANT OPTION</> can be added to a privilege type to test
13365     whether the privilege is held with grant option.  Also, multiple privilege
13366     types can be listed separated by commas, in which case the result will
13367     be <literal>true</> if any of the listed privileges is held.
13368     (Case of the privilege string is not significant, and extra whitespace
13369     is allowed between but not within privilege names.)
13370     Some examples:
13371 <programlisting>
13372 SELECT has_table_privilege('myschema.mytable', 'select');
13373 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
13374 </programlisting>
13375    </para>
13376
13377    <para>
13378     <function>has_sequence_privilege</function> checks whether a user
13379     can access a sequence in a particular way.  The possibilities for its
13380     arguments are analogous to <function>has_table_privilege</function>.
13381     The desired access privilege type must evaluate to one of
13382     <literal>USAGE</literal>,
13383     <literal>SELECT</literal>, or
13384     <literal>UPDATE</literal>.
13385    </para>
13386
13387    <para>
13388     <function>has_any_column_privilege</function> checks whether a user can
13389     access any column of a table in a particular way.
13390     Its argument possibilities
13391     are analogous to <function>has_table_privilege</>,
13392     except that the desired access privilege type must evaluate to some
13393     combination of
13394     <literal>SELECT</literal>,
13395     <literal>INSERT</literal>,
13396     <literal>UPDATE</literal>, or
13397     <literal>REFERENCES</literal>.  Note that having any of these privileges
13398     at the table level implicitly grants it for each column of the table,
13399     so <function>has_any_column_privilege</function> will always return
13400     <literal>true</> if <function>has_table_privilege</> does for the same
13401     arguments.  But <function>has_any_column_privilege</> also succeeds if
13402     there is a column-level grant of the privilege for at least one column.
13403    </para>
13404
13405    <para>
13406     <function>has_column_privilege</function> checks whether a user
13407     can access a column in a particular way.
13408     Its argument possibilities
13409     are analogous to <function>has_table_privilege</function>,
13410     with the addition that the column can be specified either by name
13411     or attribute number.
13412     The desired access privilege type must evaluate to some combination of
13413     <literal>SELECT</literal>,
13414     <literal>INSERT</literal>,
13415     <literal>UPDATE</literal>, or
13416     <literal>REFERENCES</literal>.  Note that having any of these privileges
13417     at the table level implicitly grants it for each column of the table.
13418    </para>
13419
13420    <para>
13421     <function>has_database_privilege</function> checks whether a user
13422     can access a database in a particular way.
13423     Its argument possibilities
13424     are analogous to <function>has_table_privilege</function>.
13425     The desired access privilege type must evaluate to some combination of
13426     <literal>CREATE</literal>,
13427     <literal>CONNECT</literal>,
13428     <literal>TEMPORARY</literal>, or
13429     <literal>TEMP</literal> (which is equivalent to
13430     <literal>TEMPORARY</literal>).
13431    </para>
13432
13433    <para>
13434     <function>has_function_privilege</function> checks whether a user
13435     can access a function in a particular way.
13436     Its argument possibilities
13437     are analogous to <function>has_table_privilege</function>.
13438     When specifying a function by a text string rather than by OID,
13439     the allowed input is the same as for the <type>regprocedure</> data type
13440     (see <xref linkend="datatype-oid">).
13441     The desired access privilege type must evaluate to
13442     <literal>EXECUTE</literal>.
13443     An example is:
13444 <programlisting>
13445 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
13446 </programlisting>
13447    </para>
13448
13449    <para>
13450     <function>has_foreign_data_wrapper_privilege</function> checks whether a user
13451     can access a foreign-data wrapper in a particular way.
13452     Its argument possibilities
13453     are analogous to <function>has_table_privilege</function>.
13454     The desired access privilege type must evaluate to
13455     <literal>USAGE</literal>.
13456    </para>
13457
13458    <para>
13459     <function>has_language_privilege</function> checks whether a user
13460     can access a procedural language in a particular way.
13461     Its argument possibilities
13462     are analogous to <function>has_table_privilege</function>.
13463     The desired access privilege type must evaluate to
13464     <literal>USAGE</literal>.
13465    </para>
13466
13467    <para>
13468     <function>has_schema_privilege</function> checks whether a user
13469     can access a schema in a particular way.
13470     Its argument possibilities
13471     are analogous to <function>has_table_privilege</function>.
13472     The desired access privilege type must evaluate to some combination of
13473     <literal>CREATE</literal> or
13474     <literal>USAGE</literal>.
13475    </para>
13476
13477    <para>
13478     <function>has_server_privilege</function> checks whether a user
13479     can access a foreign server in a particular way.
13480     Its argument possibilities
13481     are analogous to <function>has_table_privilege</function>.
13482     The desired access privilege type must evaluate to
13483     <literal>USAGE</literal>.
13484    </para>
13485
13486    <para>
13487     <function>has_tablespace_privilege</function> checks whether a user
13488     can access a tablespace in a particular way.
13489     Its argument possibilities
13490     are analogous to <function>has_table_privilege</function>.
13491     The desired access privilege type must evaluate to
13492     <literal>CREATE</literal>.
13493    </para>
13494
13495    <para>
13496     <function>pg_has_role</function> checks whether a user
13497     can access a role in a particular way.
13498     Its argument possibilities
13499     are analogous to <function>has_table_privilege</function>,
13500     except that <literal>public</> is not allowed as a user name.
13501     The desired access privilege type must evaluate to some combination of
13502     <literal>MEMBER</literal> or
13503     <literal>USAGE</literal>.
13504     <literal>MEMBER</literal> denotes direct or indirect membership in
13505     the role (that is, the right to do <command>SET ROLE</>), while
13506     <literal>USAGE</literal> denotes whether the privileges of the role
13507     are immediately available without doing <command>SET ROLE</>.
13508    </para>
13509
13510   <para>
13511    <xref linkend="functions-info-schema-table"> shows functions that
13512    determine whether a certain object is <firstterm>visible</> in the
13513    current schema search path.
13514    For example, a table is said to be visible if its
13515    containing schema is in the search path and no table of the same
13516    name appears earlier in the search path.  This is equivalent to the
13517    statement that the table can be referenced by name without explicit
13518    schema qualification.  To list the names of all visible tables:
13519 <programlisting>
13520 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
13521 </programlisting>
13522   </para>
13523
13524    <indexterm>
13525     <primary>search path</primary>
13526     <secondary>object visibility</secondary>
13527    </indexterm>
13528
13529    <table id="functions-info-schema-table">
13530     <title>Schema Visibility Inquiry Functions</title>
13531     <tgroup cols="3">
13532      <thead>
13533       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13534      </thead>
13535
13536      <tbody>
13537       <row>
13538        <entry><literal><function>pg_collation_is_visible(<parameter>collation_oid</parameter>)</function></literal>
13539        </entry>
13540        <entry><type>boolean</type></entry>
13541        <entry>is collation visible in search path</entry>
13542       </row>
13543       <row>
13544        <entry><literal><function>pg_conversion_is_visible(<parameter>conversion_oid</parameter>)</function></literal>
13545        </entry>
13546        <entry><type>boolean</type></entry>
13547        <entry>is conversion visible in search path</entry>
13548       </row>
13549       <row>
13550        <entry><literal><function>pg_function_is_visible(<parameter>function_oid</parameter>)</function></literal>
13551        </entry>
13552        <entry><type>boolean</type></entry>
13553        <entry>is function visible in search path</entry>
13554       </row>
13555       <row>
13556        <entry><literal><function>pg_opclass_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
13557        </entry>
13558        <entry><type>boolean</type></entry>
13559        <entry>is operator class visible in search path</entry>
13560       </row>
13561       <row>
13562        <entry><literal><function>pg_operator_is_visible(<parameter>operator_oid</parameter>)</function></literal>
13563        </entry>
13564        <entry><type>boolean</type></entry>
13565        <entry>is operator visible in search path</entry>
13566       </row>
13567       <row>
13568        <entry><literal><function>pg_opfamily_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
13569        </entry>
13570        <entry><type>boolean</type></entry>
13571        <entry>is operator family visible in search path</entry>
13572       </row>
13573       <row>
13574        <entry><literal><function>pg_table_is_visible(<parameter>table_oid</parameter>)</function></literal>
13575        </entry>
13576        <entry><type>boolean</type></entry>
13577        <entry>is table visible in search path</entry>
13578       </row>
13579       <row>
13580        <entry><literal><function>pg_ts_config_is_visible(<parameter>config_oid</parameter>)</function></literal>
13581        </entry>
13582        <entry><type>boolean</type></entry>
13583        <entry>is text search configuration visible in search path</entry>
13584       </row>
13585       <row>
13586        <entry><literal><function>pg_ts_dict_is_visible(<parameter>dict_oid</parameter>)</function></literal>
13587        </entry>
13588        <entry><type>boolean</type></entry>
13589        <entry>is text search dictionary visible in search path</entry>
13590       </row>
13591       <row>
13592        <entry><literal><function>pg_ts_parser_is_visible(<parameter>parser_oid</parameter>)</function></literal>
13593        </entry>
13594        <entry><type>boolean</type></entry>
13595        <entry>is text search parser visible in search path</entry>
13596       </row>
13597       <row>
13598        <entry><literal><function>pg_ts_template_is_visible(<parameter>template_oid</parameter>)</function></literal>
13599        </entry>
13600        <entry><type>boolean</type></entry>
13601        <entry>is text search template visible in search path</entry>
13602       </row>
13603       <row>
13604        <entry><literal><function>pg_type_is_visible(<parameter>type_oid</parameter>)</function></literal>
13605        </entry>
13606        <entry><type>boolean</type></entry>
13607        <entry>is type (or domain) visible in search path</entry>
13608       </row>
13609      </tbody>
13610     </tgroup>
13611    </table>
13612
13613    <indexterm>
13614     <primary>pg_collation_is_visible</primary>
13615    </indexterm>
13616    <indexterm>
13617     <primary>pg_conversion_is_visible</primary>
13618    </indexterm>
13619    <indexterm>
13620     <primary>pg_function_is_visible</primary>
13621    </indexterm>
13622    <indexterm>
13623     <primary>pg_opclass_is_visible</primary>
13624    </indexterm>
13625    <indexterm>
13626     <primary>pg_operator_is_visible</primary>
13627    </indexterm>
13628    <indexterm>
13629     <primary>pg_opfamily_is_visible</primary>
13630    </indexterm>
13631    <indexterm>
13632     <primary>pg_table_is_visible</primary>
13633    </indexterm>
13634    <indexterm>
13635     <primary>pg_ts_config_is_visible</primary>
13636    </indexterm>
13637    <indexterm>
13638     <primary>pg_ts_dict_is_visible</primary>
13639    </indexterm>
13640    <indexterm>
13641     <primary>pg_ts_parser_is_visible</primary>
13642    </indexterm>
13643    <indexterm>
13644     <primary>pg_ts_template_is_visible</primary>
13645    </indexterm>
13646    <indexterm>
13647     <primary>pg_type_is_visible</primary>
13648    </indexterm>
13649
13650    <para>
13651     Each function performs the visibility check for one type of database
13652     object.  Note that <function>pg_table_is_visible</function> can also be used
13653     with views, indexes and sequences; <function>pg_type_is_visible</function>
13654     can also be used with domains. For functions and operators, an object in
13655     the search path is visible if there is no object of the same name
13656     <emphasis>and argument data type(s)</> earlier in the path.  For operator
13657     classes, both name and associated index access method are considered.
13658    </para>
13659
13660    <para>
13661     All these functions require object OIDs to identify the object to be
13662     checked.  If you want to test an object by name, it is convenient to use
13663     the OID alias types (<type>regclass</>, <type>regtype</>,
13664     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
13665     or <type>regdictionary</>),
13666     for example:
13667 <programlisting>
13668 SELECT pg_type_is_visible('myschema.widget'::regtype);
13669 </programlisting>
13670     Note that it would not make much sense to test a non-schema-qualified
13671     type name in this way &mdash; if the name can be recognized at all, it must be visible.
13672    </para>
13673
13674    <indexterm>
13675     <primary>format_type</primary>
13676    </indexterm>
13677
13678    <indexterm>
13679     <primary>pg_describe_object</primary>
13680    </indexterm>
13681
13682    <indexterm>
13683     <primary>pg_get_constraintdef</primary>
13684    </indexterm>
13685
13686    <indexterm>
13687     <primary>pg_get_expr</primary>
13688    </indexterm>
13689
13690    <indexterm>
13691     <primary>pg_get_functiondef</primary>
13692    </indexterm>
13693
13694    <indexterm>
13695     <primary>pg_get_function_arguments</primary>
13696    </indexterm>
13697
13698    <indexterm>
13699     <primary>pg_get_function_identity_arguments</primary>
13700    </indexterm>
13701
13702    <indexterm>
13703     <primary>pg_get_function_result</primary>
13704    </indexterm>
13705
13706    <indexterm>
13707     <primary>pg_get_indexdef</primary>
13708    </indexterm>
13709
13710    <indexterm>
13711     <primary>pg_get_keywords</primary>
13712    </indexterm>
13713
13714    <indexterm>
13715     <primary>pg_get_ruledef</primary>
13716    </indexterm>
13717
13718    <indexterm>
13719     <primary>pg_get_serial_sequence</primary>
13720    </indexterm>
13721
13722    <indexterm>
13723     <primary>pg_get_triggerdef</primary>
13724    </indexterm>
13725
13726    <indexterm>
13727     <primary>pg_get_userbyid</primary>
13728    </indexterm>
13729
13730    <indexterm>
13731     <primary>pg_get_viewdef</primary>
13732    </indexterm>
13733
13734    <indexterm>
13735     <primary>pg_options_to_table</primary>
13736    </indexterm>
13737
13738    <indexterm>
13739     <primary>pg_tablespace_databases</primary>
13740    </indexterm>
13741
13742    <indexterm>
13743     <primary>pg_tablespace_location</primary>
13744    </indexterm>
13745
13746    <indexterm>
13747     <primary>pg_typeof</primary>
13748    </indexterm>
13749
13750    <indexterm>
13751     <primary>collation for</primary>
13752    </indexterm>
13753
13754   <para>
13755    <xref linkend="functions-info-catalog-table"> lists functions that
13756    extract information from the system catalogs.
13757   </para>
13758
13759    <table id="functions-info-catalog-table">
13760     <title>System Catalog Information Functions</title>
13761     <tgroup cols="3">
13762      <thead>
13763       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13764      </thead>
13765
13766      <tbody>
13767       <row>
13768        <entry><literal><function>format_type(<parameter>type_oid</parameter>, <parameter>typemod</>)</function></literal></entry>
13769        <entry><type>text</type></entry>
13770        <entry>get SQL name of a data type</entry>
13771       </row>
13772       <row>
13773        <entry><literal><function>pg_describe_object(<parameter>catalog_id</parameter>, <parameter>object_id</parameter>, <parameter>object_sub_id</parameter>)</function></literal></entry>
13774        <entry><type>text</type></entry>
13775        <entry>get description of a database object</entry>
13776       </row>
13777       <row>
13778        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>)</function></literal></entry>
13779        <entry><type>text</type></entry>
13780        <entry>get definition of a constraint</entry>
13781       </row>
13782       <row>
13783        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13784        <entry><type>text</type></entry>
13785        <entry>get definition of a constraint</entry>
13786       </row>
13787       <row>
13788        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>)</function></literal></entry>
13789        <entry><type>text</type></entry>
13790        <entry>decompile internal form of an expression, assuming that any Vars
13791        in it refer to the relation indicated by the second parameter</entry>
13792       </row>
13793       <row>
13794        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</function></literal></entry>
13795        <entry><type>text</type></entry>
13796        <entry>decompile internal form of an expression, assuming that any Vars
13797        in it refer to the relation indicated by the second parameter</entry>
13798       </row>
13799       <row>
13800        <entry><literal><function>pg_get_functiondef(<parameter>func_oid</parameter>)</function></literal></entry>
13801        <entry><type>text</type></entry>
13802        <entry>get definition of a function</entry>
13803       </row>
13804       <row>
13805        <entry><literal><function>pg_get_function_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
13806        <entry><type>text</type></entry>
13807        <entry>get argument list of function's definition (with default values)</entry>
13808       </row>
13809       <row>
13810        <entry><literal><function>pg_get_function_identity_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
13811        <entry><type>text</type></entry>
13812        <entry>get argument list to identify a function (without default values)</entry>
13813       </row>
13814       <row>
13815        <entry><literal><function>pg_get_function_result(<parameter>func_oid</parameter>)</function></literal></entry>
13816        <entry><type>text</type></entry>
13817        <entry>get <literal>RETURNS</> clause for function</entry>
13818       </row>
13819       <row>
13820        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>)</function></literal></entry>
13821        <entry><type>text</type></entry>
13822        <entry>get <command>CREATE INDEX</> command for index</entry>
13823       </row>
13824       <row>
13825        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</function></literal></entry>
13826        <entry><type>text</type></entry>
13827        <entry>get <command>CREATE INDEX</> command for index,
13828        or definition of just one index column when
13829        <parameter>column_no</> is not zero</entry>
13830       </row>
13831       <row>
13832        <entry><literal><function>pg_get_keywords()</function></literal></entry>
13833        <entry><type>setof record</type></entry>
13834        <entry>get list of SQL keywords and their categories</entry>
13835       </row>
13836       <row>
13837        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>)</function></literal></entry>
13838        <entry><type>text</type></entry>
13839        <entry>get <command>CREATE RULE</> command for rule</entry>
13840       </row>
13841       <row>
13842        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13843        <entry><type>text</type></entry>
13844        <entry>get <command>CREATE RULE</> command for rule</entry>
13845       </row>
13846       <row>
13847        <entry><literal><function>pg_get_serial_sequence(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</function></literal></entry>
13848        <entry><type>text</type></entry>
13849        <entry>get name of the sequence that a <type>serial</type>, <type>smallserial</type> or <type>bigserial</type> column
13850        uses</entry>
13851       </row>
13852       <row>
13853        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
13854        <entry><type>text</type></entry>
13855        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
13856       </row>
13857       <row>
13858        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>, <parameter>pretty_bool</>)</entry>
13859        <entry><type>text</type></entry>
13860        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
13861       </row>
13862       <row>
13863        <entry><literal><function>pg_get_userbyid(<parameter>role_oid</parameter>)</function></literal></entry>
13864        <entry><type>name</type></entry>
13865        <entry>get role name with given OID</entry>
13866       </row>
13867       <row>
13868        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>)</function></literal></entry>
13869        <entry><type>text</type></entry>
13870        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
13871       </row>
13872       <row>
13873        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13874        <entry><type>text</type></entry>
13875        <entry>get underlying <command>SELECT</command> command for view;
13876               lines with fields are wrapped to 80 columns if <parameter>pretty_bool</parameter> is true (<emphasis>deprecated</emphasis>)</entry>
13877       </row>
13878       <row>
13879        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>)</function></literal></entry>
13880        <entry><type>text</type></entry>
13881        <entry>get underlying <command>SELECT</command> command for view</entry>
13882       </row>
13883       <row>
13884        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13885        <entry><type>text</type></entry>
13886        <entry>get underlying <command>SELECT</command> command for view;
13887               lines with fields are wrapped to 80 columns if <parameter>pretty_bool</parameter> is true</entry>
13888       </row>
13889       <row>
13890        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>wrap_column_int</>)</function></literal></entry>
13891        <entry><type>text</type></entry>
13892        <entry>get underlying <command>SELECT</command> command for view;
13893               lines with fields are wrapped to specified number of columns,
13894               pretty printing is implied</entry>
13895       </row>
13896       <row>
13897        <entry><literal><function>pg_options_to_table(<parameter>reloptions</parameter>)</function></literal></entry>
13898        <entry><type>setof record</type></entry>
13899        <entry>get the set of storage option name/value pairs</entry>
13900       </row>
13901       <row>
13902        <entry><literal><function>pg_tablespace_databases(<parameter>tablespace_oid</parameter>)</function></literal></entry>
13903        <entry><type>setof oid</type></entry>
13904        <entry>get the set of database OIDs that have objects in the tablespace</entry>
13905       </row>
13906       <row>
13907        <entry><literal><function>pg_tablespace_location(<parameter>tablespace_oid</parameter>)</function></literal></entry>
13908        <entry><type>text</type></entry>
13909        <entry>get the path in the file system that this tablespace is located in</entry>
13910       </row>
13911       <row>
13912        <entry><literal><function>pg_typeof(<parameter>any</parameter>)</function></literal></entry>
13913        <entry><type>regtype</type></entry>
13914        <entry>get the data type of any value</entry>
13915       </row>
13916       <row>
13917        <entry><literal><function>collation for (<parameter>any</parameter>)</function></literal></entry>
13918        <entry><type>text</type></entry>
13919        <entry>get the collation of the argument</entry>
13920       </row>
13921      </tbody>
13922     </tgroup>
13923    </table>
13924
13925   <para>
13926    <function>format_type</function> returns the SQL name of a data type that
13927    is identified by its type OID and possibly a type modifier.  Pass NULL
13928    for the type modifier if no specific modifier is known.
13929   </para>
13930
13931   <para>
13932    <function>pg_get_keywords</function> returns a set of records describing
13933    the SQL keywords recognized by the server. The <structfield>word</> column
13934    contains the keyword.  The <structfield>catcode</> column contains a
13935    category code: <literal>U</> for unreserved, <literal>C</> for column name,
13936    <literal>T</> for type or function name, or <literal>R</> for reserved.
13937    The <structfield>catdesc</> column contains a possibly-localized string
13938    describing the category.
13939   </para>
13940
13941   <para>
13942    <function>pg_get_constraintdef</function>,
13943    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
13944    and <function>pg_get_triggerdef</function>, respectively reconstruct the
13945    creating command for a constraint, index, rule, or trigger. (Note that this
13946    is a decompiled reconstruction, not the original text of the command.)
13947    <function>pg_get_expr</function> decompiles the internal form of an
13948    individual expression, such as the default value for a column.  It can be
13949    useful when examining the contents of system catalogs.  If the expression
13950    might contain Vars, specify the OID of the relation they refer to as the
13951    second parameter; if no Vars are expected, zero is sufficient.
13952    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
13953    query that defines a view. Most of these functions come in two variants,
13954    one of which can optionally <quote>pretty-print</> the result.  The
13955    pretty-printed format is more readable, but the default format is more
13956    likely to be interpreted the same way by future versions of
13957    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
13958    purposes.  Passing <literal>false</> for the pretty-print parameter yields
13959    the same result as the variant that does not have the parameter at all.
13960   </para>
13961
13962   <para>
13963    <function>pg_get_functiondef</> returns a complete
13964    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
13965    <function>pg_get_function_arguments</function> returns the argument list
13966    of a function, in the form it would need to appear in within
13967    <command>CREATE FUNCTION</>.
13968    <function>pg_get_function_result</function> similarly returns the
13969    appropriate <literal>RETURNS</> clause for the function.
13970    <function>pg_get_function_identity_arguments</function> returns the
13971    argument list necessary to identify a function, in the form it
13972    would need to appear in within <command>ALTER FUNCTION</>, for
13973    instance.  This form omits default values.
13974   </para>
13975
13976   <para>
13977    <function>pg_get_serial_sequence</function> returns the name of the
13978    sequence associated with a column, or NULL if no sequence is associated
13979    with the column.  The first input parameter is a table name with
13980    optional schema, and the second parameter is a column name.  Because
13981    the first parameter is potentially a schema and table, it is not treated
13982    as a double-quoted identifier, meaning it is lower cased by default,
13983    while the second parameter, being just a column name, is treated as
13984    double-quoted and has its case preserved.  The function returns a value
13985    suitably formatted for passing to sequence functions (see <xref
13986    linkend="functions-sequence">).  This association can be modified or
13987    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
13988    probably should have been called
13989    <function>pg_get_owned_sequence</function>; its current name reflects the fact
13990    that it's typically used with <type>serial</> or <type>bigserial</>
13991    columns.)
13992   </para>
13993
13994   <para>
13995    <function>pg_get_userbyid</function> extracts a role's name given
13996    its OID.
13997   </para>
13998
13999   <para>
14000    <function>pg_options_to_table</function> returns the set of storage
14001    option name/value pairs
14002    (<literal>option_name</>/<literal>option_value</>) when passed
14003    <structname>pg_class</>.<structfield>reloptions</> or
14004    <structname>pg_attribute</>.<structfield>attoptions</>.
14005   </para>
14006
14007   <para>
14008    <function>pg_tablespace_databases</function> allows a tablespace to be
14009    examined. It returns the set of OIDs of databases that have objects stored
14010    in the tablespace. If this function returns any rows, the tablespace is not
14011    empty and cannot be dropped. To display the specific objects populating the
14012    tablespace, you will need to connect to the databases identified by
14013    <function>pg_tablespace_databases</function> and query their
14014    <structname>pg_class</> catalogs.
14015   </para>
14016
14017   <para>
14018    <function>pg_describe_object</function> returns a description of a database
14019    object specified by catalog OID, object OID and a (possibly zero) sub-object ID.
14020    This is useful to determine the identity of an object as stored in the
14021    <structname>pg_depend</structname> catalog.
14022   </para>
14023
14024   <para>
14025    <function>pg_typeof</function> returns the OID of the data type of the
14026    value that is passed to it.  This can be helpful for troubleshooting or
14027    dynamically constructing SQL queries.  The function is declared as
14028    returning <type>regtype</>, which is an OID alias type (see
14029    <xref linkend="datatype-oid">); this means that it is the same as an
14030    OID for comparison purposes but displays as a type name.  For example:
14031 <programlisting>
14032 SELECT pg_typeof(33);
14033
14034  pg_typeof 
14035 -----------
14036  integer
14037 (1 row)
14038
14039 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
14040  typlen 
14041 --------
14042       4
14043 (1 row)
14044 </programlisting>
14045   </para>
14046
14047   <para>
14048    The expression <literal>collation for</literal> returns the collation of the
14049    value that is passed to it.  Example:
14050 <programlisting>
14051 SELECT collation for (description) FROM pg_description LIMIT 1;
14052  pg_collation_for 
14053 ------------------
14054  "default"
14055 (1 row)
14056
14057 SELECT collation for ('foo' COLLATE "de_DE");
14058  pg_collation_for 
14059 ------------------
14060  "de_DE"
14061 (1 row)
14062 </programlisting>
14063   The value might be quoted and schema-qualified.  If no collation is derived
14064   for the argument expression, then a null value is returned.  If the argument
14065   is not of a collatable data type, then an error is raised.
14066   </para>
14067
14068    <indexterm>
14069     <primary>col_description</primary>
14070    </indexterm>
14071
14072    <indexterm>
14073     <primary>obj_description</primary>
14074    </indexterm>
14075
14076    <indexterm>
14077     <primary>shobj_description</primary>
14078    </indexterm>
14079
14080    <indexterm>
14081     <primary>comment</primary>
14082     <secondary sortas="database objects">about database objects</secondary>
14083    </indexterm>
14084
14085    <para>
14086     The functions shown in <xref linkend="functions-info-comment-table">
14087     extract comments previously stored with the <xref linkend="sql-comment">
14088     command.  A null value is returned if no
14089     comment could be found for the specified parameters.
14090    </para>
14091
14092    <table id="functions-info-comment-table">
14093     <title>Comment Information Functions</title>
14094     <tgroup cols="3">
14095      <thead>
14096       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14097      </thead>
14098
14099      <tbody>
14100       <row>
14101        <entry><literal><function>col_description(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</function></literal></entry>
14102        <entry><type>text</type></entry>
14103        <entry>get comment for a table column</entry>
14104       </row>
14105       <row>
14106        <entry><literal><function>obj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
14107        <entry><type>text</type></entry>
14108        <entry>get comment for a database object</entry>
14109       </row>
14110       <row>
14111        <entry><literal><function>obj_description(<parameter>object_oid</parameter>)</function></literal></entry>
14112        <entry><type>text</type></entry>
14113        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
14114       </row>
14115       <row>
14116        <entry><literal><function>shobj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
14117        <entry><type>text</type></entry>
14118        <entry>get comment for a shared database object</entry>
14119       </row>
14120      </tbody>
14121     </tgroup>
14122    </table>
14123
14124    <para>
14125     <function>col_description</function> returns the comment for a table
14126     column, which is specified by the OID of its table and its column number.
14127     (<function>obj_description</function> cannot be used for table columns
14128     since columns do not have OIDs of their own.)
14129    </para>
14130
14131    <para>
14132     The two-parameter form of <function>obj_description</function> returns the
14133     comment for a database object specified by its OID and the name of the
14134     containing system catalog.  For example,
14135     <literal>obj_description(123456,'pg_class')</literal>
14136     would retrieve the comment for the table with OID 123456.
14137     The one-parameter form of <function>obj_description</function> requires only
14138     the object OID.  It is deprecated since there is no guarantee that
14139     OIDs are unique across different system catalogs; therefore, the wrong
14140     comment might be returned.
14141    </para>
14142
14143    <para>
14144     <function>shobj_description</function> is used just like
14145     <function>obj_description</function> except it is used for retrieving
14146     comments on shared objects.  Some system catalogs are global to all
14147     databases within each cluster, and the descriptions for objects in them
14148     are stored globally as well.
14149    </para>
14150
14151    <indexterm>
14152     <primary>txid_current</primary>
14153    </indexterm>
14154
14155    <indexterm>
14156     <primary>txid_current_snapshot</primary>
14157    </indexterm>
14158
14159    <indexterm>
14160     <primary>txid_snapshot_xip</primary>
14161    </indexterm>
14162
14163    <indexterm>
14164     <primary>txid_snapshot_xmax</primary>
14165    </indexterm>
14166
14167    <indexterm>
14168     <primary>txid_snapshot_xmin</primary>
14169    </indexterm>
14170
14171    <indexterm>
14172     <primary>txid_visible_in_snapshot</primary>
14173    </indexterm>
14174
14175    <para>
14176     The functions shown in <xref linkend="functions-txid-snapshot">
14177     provide server transaction information in an exportable form.  The main
14178     use of these functions is to determine which transactions were committed
14179     between two snapshots.
14180    </para>
14181
14182    <table id="functions-txid-snapshot">
14183     <title>Transaction IDs and Snapshots</title>
14184     <tgroup cols="3">
14185      <thead>
14186       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14187      </thead>
14188
14189      <tbody>
14190       <row>
14191        <entry><literal><function>txid_current()</function></literal></entry>
14192        <entry><type>bigint</type></entry>
14193        <entry>get current transaction ID</entry>
14194       </row>
14195       <row>
14196        <entry><literal><function>txid_current_snapshot()</function></literal></entry>
14197        <entry><type>txid_snapshot</type></entry>
14198        <entry>get current snapshot</entry>
14199       </row>
14200       <row>
14201        <entry><literal><function>txid_snapshot_xip(<parameter>txid_snapshot</parameter>)</function></literal></entry>
14202        <entry><type>setof bigint</type></entry>
14203        <entry>get in-progress transaction IDs in snapshot</entry>
14204       </row>
14205       <row>
14206        <entry><literal><function>txid_snapshot_xmax(<parameter>txid_snapshot</parameter>)</function></literal></entry>
14207        <entry><type>bigint</type></entry>
14208        <entry>get <literal>xmax</literal> of snapshot</entry>
14209       </row>
14210       <row>
14211        <entry><literal><function>txid_snapshot_xmin(<parameter>txid_snapshot</parameter>)</function></literal></entry>
14212        <entry><type>bigint</type></entry>
14213        <entry>get <literal>xmin</literal> of snapshot</entry>
14214       </row>
14215       <row>
14216        <entry><literal><function>txid_visible_in_snapshot(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</function></literal></entry>
14217        <entry><type>boolean</type></entry>
14218        <entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
14219       </row>
14220      </tbody>
14221     </tgroup>
14222    </table>
14223
14224    <para>
14225     The internal transaction ID type (<type>xid</>) is 32 bits wide and
14226     wraps around every 4 billion transactions.  However, these functions
14227     export a 64-bit format that is extended with an <quote>epoch</> counter
14228     so it will not wrap around during the life of an installation.
14229     The data type used by these functions, <type>txid_snapshot</type>,
14230     stores information about transaction ID
14231     visibility at a particular moment in time.  Its components are
14232     described in <xref linkend="functions-txid-snapshot-parts">.
14233    </para>
14234
14235    <table id="functions-txid-snapshot-parts">
14236     <title>Snapshot Components</title>
14237     <tgroup cols="2">
14238      <thead>
14239       <row>
14240        <entry>Name</entry>
14241        <entry>Description</entry>
14242       </row>
14243      </thead>
14244
14245      <tbody>
14246
14247       <row>
14248        <entry><type>xmin</type></entry>
14249        <entry>
14250          Earliest transaction ID (txid) that is still active.  All earlier
14251          transactions will either be committed and visible, or rolled
14252          back and dead.
14253        </entry>
14254       </row>
14255
14256       <row>
14257        <entry><type>xmax</type></entry>
14258        <entry>
14259         First as-yet-unassigned txid.  All txids greater than or equal to this
14260         are not yet started as of the time of the snapshot, and thus invisible.
14261        </entry>
14262       </row>
14263
14264       <row>
14265        <entry><type>xip_list</type></entry>
14266        <entry>
14267         Active txids at the time of the snapshot.  The list
14268         includes only those active txids between <literal>xmin</>
14269         and <literal>xmax</>; there might be active txids higher
14270         than <literal>xmax</>.  A txid that is <literal>xmin &lt;= txid &lt;
14271         xmax</literal> and not in this list was already completed
14272         at the time of the snapshot, and thus either visible or
14273         dead according to its commit status.  The list does not
14274         include txids of subtransactions.
14275        </entry>
14276       </row>
14277
14278      </tbody>
14279     </tgroup>
14280    </table>
14281
14282    <para>
14283     <type>txid_snapshot</>'s textual representation is
14284     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
14285     For example <literal>10:20:10,14,15</literal> means
14286     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
14287    </para>
14288   </sect1>
14289
14290   <sect1 id="functions-admin">
14291    <title>System Administration Functions</title>
14292
14293    <para>
14294     The functions described in this section are used to control and
14295     monitor a <productname>PostgreSQL</> installation.
14296    </para>
14297
14298   <sect2 id="functions-admin-set">
14299    <title>Configuration Settings Functions</title>
14300
14301    <para>
14302     <xref linkend="functions-admin-set-table"> shows the functions
14303     available to query and alter run-time configuration parameters.
14304    </para>
14305
14306    <table id="functions-admin-set-table">
14307     <title>Configuration Settings Functions</title>
14308     <tgroup cols="3">
14309      <thead>
14310       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
14311      </thead>
14312
14313      <tbody>
14314       <row>
14315        <entry>
14316         <indexterm>
14317          <primary>current_setting</primary>
14318         </indexterm>
14319         <literal><function>current_setting(<parameter>setting_name</parameter>)</function></literal>
14320        </entry>
14321        <entry><type>text</type></entry>
14322        <entry>get current value of setting</entry>
14323       </row>
14324       <row>
14325        <entry>
14326         <indexterm>
14327          <primary>set_config</primary>
14328         </indexterm>
14329         <literal><function>set_config(<parameter>setting_name</parameter>,
14330                              <parameter>new_value</parameter>,
14331                              <parameter>is_local</parameter>)</function></literal>
14332        </entry>
14333        <entry><type>text</type></entry>
14334        <entry>set parameter and return new value</entry>
14335       </row>
14336      </tbody>
14337     </tgroup>
14338    </table>
14339
14340    <indexterm>
14341     <primary>SET</primary>
14342    </indexterm>
14343
14344    <indexterm>
14345     <primary>SHOW</primary>
14346    </indexterm>
14347
14348    <indexterm>
14349     <primary>configuration</primary>
14350     <secondary sortas="server">of the server</secondary>
14351     <tertiary>functions</tertiary>
14352    </indexterm>
14353
14354    <para>
14355     The function <function>current_setting</function> yields the
14356     current value of the setting <parameter>setting_name</parameter>.
14357     It corresponds to the <acronym>SQL</acronym> command
14358     <command>SHOW</command>.  An example:
14359 <programlisting>
14360 SELECT current_setting('datestyle');
14361
14362  current_setting
14363 -----------------
14364  ISO, MDY
14365 (1 row)
14366 </programlisting>
14367    </para>
14368
14369    <para>
14370     <function>set_config</function> sets the parameter
14371     <parameter>setting_name</parameter> to
14372     <parameter>new_value</parameter>.  If
14373     <parameter>is_local</parameter> is <literal>true</literal>, the
14374     new value will only apply to the current transaction. If you want
14375     the new value to apply for the current session, use
14376     <literal>false</literal> instead. The function corresponds to the
14377     SQL command <command>SET</command>. An example:
14378 <programlisting>
14379 SELECT set_config('log_statement_stats', 'off', false);
14380
14381  set_config
14382 ------------
14383  off
14384 (1 row)
14385 </programlisting>
14386    </para>
14387
14388   </sect2>
14389
14390   <sect2 id="functions-admin-signal">
14391    <title>Server Signalling Functions</title>
14392
14393    <indexterm>
14394     <primary>pg_cancel_backend</primary>
14395    </indexterm>
14396    <indexterm>
14397     <primary>pg_reload_conf</primary>
14398    </indexterm>
14399    <indexterm>
14400     <primary>pg_rotate_logfile</primary>
14401    </indexterm>
14402    <indexterm>
14403     <primary>pg_terminate_backend</primary>
14404    </indexterm>
14405
14406    <indexterm>
14407     <primary>signal</primary>
14408     <secondary sortas="backend">backend processes</secondary>
14409    </indexterm>
14410
14411    <para>
14412     The functions shown in <xref
14413     linkend="functions-admin-signal-table"> send control signals to
14414     other server processes.  Use of these functions is usually restricted
14415     to superusers, with noted exceptions.
14416    </para>
14417
14418    <table id="functions-admin-signal-table">
14419     <title>Server Signalling Functions</title>
14420     <tgroup cols="3">
14421      <thead>
14422       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14423       </row>
14424      </thead>
14425
14426      <tbody>
14427       <row>
14428        <entry>
14429         <literal><function>pg_cancel_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
14430         </entry>
14431        <entry><type>boolean</type></entry>
14432        <entry>Cancel a backend's current query.  You can execute this against
14433         another backend that has exactly the same role as the user calling the
14434         function.  In all other cases, you must be a superuser.
14435         </entry>
14436       </row>
14437       <row>
14438        <entry>
14439         <literal><function>pg_reload_conf()</function></literal>
14440         </entry>
14441        <entry><type>boolean</type></entry>
14442        <entry>Cause server processes to reload their configuration files</entry>
14443       </row>
14444       <row>
14445        <entry>
14446         <literal><function>pg_rotate_logfile()</function></literal>
14447         </entry>
14448        <entry><type>boolean</type></entry>
14449        <entry>Rotate server's log file</entry>
14450       </row>
14451       <row>
14452        <entry>
14453         <literal><function>pg_terminate_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
14454         </entry>
14455        <entry><type>boolean</type></entry>
14456        <entry>Terminate a backend.  You can execute this against
14457         another backend that has exactly the same role as the user
14458         calling the function.  In all other cases, you must be a
14459         superuser.
14460        </entry>
14461       </row>
14462      </tbody>
14463     </tgroup>
14464    </table>
14465
14466    <para>
14467     Each of these functions returns <literal>true</literal> if
14468     successful and <literal>false</literal> otherwise.
14469    </para>
14470
14471    <para>
14472     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
14473     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
14474     respectively) to backend processes identified by process ID.
14475     The process ID of an active backend can be found from
14476     the <structfield>pid</structfield> column of the
14477     <structname>pg_stat_activity</structname> view, or by listing the
14478     <command>postgres</command> processes on the server (using
14479     <application>ps</> on Unix or the <application>Task
14480     Manager</> on <productname>Windows</>).
14481     The role of an active backend can be found from the
14482     <structfield>usename</structfield> column of the
14483     <structname>pg_stat_activity</structname> view.
14484    </para>
14485
14486    <para>
14487     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
14488     to the server, causing configuration files
14489     to be reloaded by all server processes.
14490    </para>
14491
14492    <para>
14493     <function>pg_rotate_logfile</> signals the log-file manager to switch
14494     to a new output file immediately.  This works only when the built-in
14495     log collector is running, since otherwise there is no log-file manager
14496     subprocess.
14497    </para>
14498
14499   </sect2>
14500
14501   <sect2 id="functions-admin-backup">
14502    <title>Backup Control Functions</title>
14503
14504    <indexterm>
14505     <primary>backup</primary>
14506    </indexterm>
14507    <indexterm>
14508     <primary>pg_create_restore_point</primary>
14509    </indexterm>
14510    <indexterm>
14511     <primary>pg_current_xlog_insert_location</primary>
14512    </indexterm>
14513    <indexterm>
14514     <primary>pg_current_xlog_location</primary>
14515    </indexterm>
14516    <indexterm>
14517     <primary>pg_start_backup</primary>
14518    </indexterm>
14519    <indexterm>
14520     <primary>pg_stop_backup</primary>
14521    </indexterm>
14522    <indexterm>
14523     <primary>pg_is_in_backup</primary>
14524    </indexterm>
14525    <indexterm>
14526     <primary>pg_backup_start_time</primary>
14527    </indexterm>
14528    <indexterm>
14529     <primary>pg_switch_xlog</primary>
14530    </indexterm>
14531    <indexterm>
14532     <primary>pg_xlogfile_name</primary>
14533    </indexterm>
14534    <indexterm>
14535     <primary>pg_xlogfile_name_offset</primary>
14536    </indexterm>
14537    <indexterm>
14538     <primary>pg_xlog_location_diff</primary>
14539    </indexterm>
14540
14541    <para>
14542     The functions shown in <xref
14543     linkend="functions-admin-backup-table"> assist in making on-line backups.
14544     These functions cannot be executed during recovery (except
14545     <function>pg_is_in_backup</function>, <function>pg_backup_start_time</function>
14546     and <function>pg_xlog_location_diff</function>).
14547    </para>
14548
14549    <table id="functions-admin-backup-table">
14550     <title>Backup Control Functions</title>
14551     <tgroup cols="3">
14552      <thead>
14553       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14554       </row>
14555      </thead>
14556
14557      <tbody>
14558       <row>
14559        <entry>
14560         <literal><function>pg_create_restore_point(<parameter>name</> <type>text</>)</function></literal>
14561         </entry>
14562        <entry><type>text</type></entry>
14563        <entry>Create a named point for performing restore (restricted to superusers)</entry>
14564       </row>
14565       <row>
14566        <entry>
14567         <literal><function>pg_current_xlog_insert_location()</function></literal>
14568         </entry>
14569        <entry><type>text</type></entry>
14570        <entry>Get current transaction log insert location</entry>
14571       </row>
14572       <row>
14573        <entry>
14574         <literal><function>pg_current_xlog_location()</function></literal>
14575         </entry>
14576        <entry><type>text</type></entry>
14577        <entry>Get current transaction log write location</entry>
14578       </row>
14579       <row>
14580        <entry>
14581         <literal><function>pg_start_backup(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> </optional>)</function></literal>
14582         </entry>
14583        <entry><type>text</type></entry>
14584        <entry>Prepare for performing on-line backup (restricted to superusers or replication roles)</entry>
14585       </row>
14586       <row>
14587        <entry>
14588         <literal><function>pg_stop_backup()</function></literal>
14589         </entry>
14590        <entry><type>text</type></entry>
14591        <entry>Finish performing on-line backup (restricted to superusers or replication roles)</entry>
14592       </row>
14593       <row>
14594        <entry>
14595         <literal><function>pg_is_in_backup()</function></literal>
14596         </entry>
14597        <entry><type>bool</type></entry>
14598        <entry>True if an on-line exclusive backup is still in progress.</entry>
14599       </row>
14600       <row>
14601        <entry>
14602         <literal><function>pg_backup_start_time()</function></literal>
14603         </entry>
14604        <entry><type>timestamp with time zone</type></entry>
14605        <entry>Get start time of an on-line exclusive backup in progress.</entry>
14606       </row>
14607       <row>
14608        <entry>
14609         <literal><function>pg_switch_xlog()</function></literal>
14610         </entry>
14611        <entry><type>text</type></entry>
14612        <entry>Force switch to a new transaction log file (restricted to superusers)</entry>
14613       </row>
14614       <row>
14615        <entry>
14616         <literal><function>pg_xlogfile_name(<parameter>location</> <type>text</>)</function></literal>
14617         </entry>
14618        <entry><type>text</type></entry>
14619        <entry>Convert transaction log location string to file name</entry>
14620       </row>
14621       <row>
14622        <entry>
14623         <literal><function>pg_xlogfile_name_offset(<parameter>location</> <type>text</>)</function></literal>
14624         </entry>
14625        <entry><type>text</>, <type>integer</></entry>
14626        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
14627       </row>
14628       <row>
14629        <entry>
14630         <literal><function>pg_xlog_location_diff(<parameter>location</> <type>text</>, <parameter>location</> <type>text</>)</function></literal>
14631        </entry>
14632        <entry><type>numeric</></entry>
14633        <entry>Calculate the difference between two transaction log locations</entry>
14634       </row>
14635      </tbody>
14636     </tgroup>
14637    </table>
14638
14639    <para>
14640     <function>pg_start_backup</> accepts an
14641     arbitrary user-defined label for the backup.  (Typically this would be
14642     the name under which the backup dump file will be stored.)  The function
14643     writes a backup label file (<filename>backup_label</>) into the
14644     database cluster's data directory, performs a checkpoint,
14645     and then returns the backup's starting transaction log location as text.
14646     The user can ignore this result value, but it is
14647     provided in case it is useful.
14648 <programlisting>
14649 postgres=# select pg_start_backup('label_goes_here');
14650  pg_start_backup
14651 -----------------
14652  0/D4445B8
14653 (1 row)
14654 </programlisting>
14655     There is an optional second parameter of type <type>boolean</type>.  If <literal>true</>,
14656     it specifies executing <function>pg_start_backup</> as quickly as
14657     possible.  This forces an immediate checkpoint which will cause a
14658     spike in I/O operations, slowing any concurrently executing queries.
14659    </para>
14660
14661    <para>
14662     <function>pg_stop_backup</> removes the label file created by
14663     <function>pg_start_backup</>, and creates a backup history file in
14664     the transaction log archive area.  The history file includes the label given to
14665     <function>pg_start_backup</>, the starting and ending transaction log locations for
14666     the backup, and the starting and ending times of the backup.  The return
14667     value is the backup's ending transaction log location (which again
14668     can be ignored).  After recording the ending location, the current
14669     transaction log insertion
14670     point is automatically advanced to the next transaction log file, so that the
14671     ending transaction log file can be archived immediately to complete the backup.
14672    </para>
14673
14674    <para>
14675     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the
14676     current file to be archived (assuming you are using continuous archiving).
14677     The return value is the ending transaction log location + 1 within the just-completed transaction log file.
14678     If there has been no transaction log activity since the last transaction log switch,
14679     <function>pg_switch_xlog</> does nothing and returns the start location
14680     of the transaction log file currently in use.
14681    </para>
14682
14683    <para>
14684     <function>pg_create_restore_point</> creates a named transaction log
14685     record that can be used as recovery target, and returns the corresponding
14686     transaction log location.  The given name can then be used with
14687     <xref linkend="recovery-target-name"> to specify the point up to which
14688     recovery will proceed.  Avoid creating multiple restore points with the
14689     same name, since recovery will stop at the first one whose name matches
14690     the recovery target.
14691    </para>
14692
14693    <para>
14694     <function>pg_current_xlog_location</> displays the current transaction log write
14695     location in the same format used by the above functions.  Similarly,
14696     <function>pg_current_xlog_insert_location</> displays the current transaction log
14697     insertion point.  The insertion point is the <quote>logical</> end
14698     of the transaction log
14699     at any instant, while the write location is the end of what has actually
14700     been written out from the server's internal buffers.  The write location
14701     is the end of what can be examined from outside the server, and is usually
14702     what you want if you are interested in archiving partially-complete transaction log
14703     files.  The insertion point is made available primarily for server
14704     debugging purposes.  These are both read-only operations and do not
14705     require superuser permissions.
14706    </para>
14707
14708    <para>
14709     You can use <function>pg_xlogfile_name_offset</> to extract the
14710     corresponding transaction log file name and byte offset from the results of any of the
14711     above functions.  For example:
14712 <programlisting>
14713 postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup());
14714         file_name         | file_offset 
14715 --------------------------+-------------
14716  00000001000000000000000D |     4039624
14717 (1 row)
14718 </programlisting>
14719     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
14720     When the given transaction log location is exactly at a transaction log file boundary, both
14721     these functions return the name of the preceding transaction log file.
14722     This is usually the desired behavior for managing transaction log archiving
14723     behavior, since the preceding file is the last one that currently
14724     needs to be archived.
14725    </para>
14726
14727    <para>
14728     <function>pg_xlog_location_diff</> calculates the difference in bytes
14729     between two transaction log locations. It can be used with
14730     <structname>pg_stat_replication</structname> or some functions shown in
14731     <xref linkend="functions-admin-backup-table"> to get the replication lag.
14732    </para>
14733
14734    <para>
14735     For details about proper usage of these functions, see
14736     <xref linkend="continuous-archiving">.
14737    </para>
14738
14739   </sect2>
14740
14741   <sect2 id="functions-recovery-control">
14742    <title>Recovery Control Functions</title>
14743
14744    <indexterm>
14745     <primary>pg_is_in_recovery</primary>
14746    </indexterm>
14747    <indexterm>
14748     <primary>pg_last_xlog_receive_location</primary>
14749    </indexterm>
14750    <indexterm>
14751     <primary>pg_last_xlog_replay_location</primary>
14752    </indexterm>
14753    <indexterm>
14754     <primary>pg_last_xact_replay_timestamp</primary>
14755    </indexterm>
14756
14757    <para>
14758     The functions shown in <xref
14759     linkend="functions-recovery-info-table"> provide information
14760     about the current status of the standby.
14761     These functions may be executed both during recovery and in normal running.
14762    </para>
14763
14764    <table id="functions-recovery-info-table">
14765     <title>Recovery Information Functions</title>
14766     <tgroup cols="3">
14767      <thead>
14768       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14769       </row>
14770      </thead>
14771
14772      <tbody>
14773       <row>
14774        <entry>
14775         <literal><function>pg_is_in_recovery()</function></literal>
14776         </entry>
14777        <entry><type>bool</type></entry>
14778        <entry>True if recovery is still in progress.
14779        </entry>
14780       </row>
14781       <row>
14782        <entry>
14783         <literal><function>pg_last_xlog_receive_location()</function></literal>
14784         </entry>
14785        <entry><type>text</type></entry>
14786        <entry>Get last transaction log location received and synced to disk by
14787         streaming replication. While streaming replication is in progress
14788         this will increase monotonically. If recovery has completed this will
14789         remain static at
14790         the value of the last WAL record received and synced to disk during
14791         recovery. If streaming replication is disabled, or if it has not yet
14792         started, the function returns NULL.
14793        </entry>
14794       </row>
14795       <row>
14796        <entry>
14797         <literal><function>pg_last_xlog_replay_location()</function></literal>
14798         </entry>
14799        <entry><type>text</type></entry>
14800        <entry>Get last transaction log location replayed during recovery.
14801         If recovery is still in progress this will increase monotonically.
14802         If recovery has completed then this value will remain static at
14803         the value of the last WAL record applied during that recovery.
14804         When the server has been started normally without recovery
14805         the function returns NULL.
14806        </entry>
14807       </row>
14808       <row>
14809        <entry>
14810         <literal><function>pg_last_xact_replay_timestamp()</function></literal>
14811         </entry>
14812        <entry><type>timestamp with time zone</type></entry>
14813        <entry>Get time stamp of last transaction replayed during recovery.
14814         This is the time at which the commit or abort WAL record for that
14815         transaction was generated on the primary.
14816         If no transactions have been replayed during recovery, this function
14817         returns NULL.  Otherwise, if recovery is still in progress this will
14818         increase monotonically.  If recovery has completed then this value will
14819         remain static at the value of the last transaction applied during that
14820         recovery.  When the server has been started normally without recovery
14821         the function returns NULL.
14822        </entry>
14823       </row>
14824      </tbody>
14825     </tgroup>
14826    </table>
14827
14828    <indexterm>
14829     <primary>pg_is_xlog_replay_paused</primary>
14830    </indexterm>
14831    <indexterm>
14832     <primary>pg_xlog_replay_pause</primary>
14833    </indexterm>
14834    <indexterm>
14835     <primary>pg_xlog_replay_resume</primary>
14836    </indexterm>
14837
14838    <para>
14839     The functions shown in <xref
14840     linkend="functions-recovery-control-table"> control the progress of recovery.
14841     These functions may be executed only during recovery.
14842    </para>
14843
14844    <table id="functions-recovery-control-table">
14845     <title>Recovery Control Functions</title>
14846     <tgroup cols="3">
14847      <thead>
14848       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14849       </row>
14850      </thead>
14851
14852      <tbody>
14853       <row>
14854        <entry>
14855         <literal><function>pg_is_xlog_replay_paused()</function></literal>
14856         </entry>
14857        <entry><type>bool</type></entry>
14858        <entry>True if recovery is paused.
14859        </entry>
14860       </row>
14861       <row>
14862        <entry>
14863         <literal><function>pg_xlog_replay_pause()</function></literal>
14864         </entry>
14865        <entry><type>void</type></entry>
14866        <entry>Pauses recovery immediately.
14867        </entry>
14868       </row>
14869       <row>
14870        <entry>
14871         <literal><function>pg_xlog_replay_resume()</function></literal>
14872         </entry>
14873        <entry><type>void</type></entry>
14874        <entry>Restarts recovery if it was paused.
14875        </entry>
14876       </row>
14877      </tbody>
14878     </tgroup>
14879    </table>
14880
14881    <para>
14882     While recovery is paused no further database changes are applied.
14883     If in hot standby, all new queries will see the same consistent snapshot
14884     of the database, and no further query conflicts will be generated until
14885     recovery is resumed.
14886    </para>
14887
14888    <para>
14889     If streaming replication is disabled, the paused state may continue
14890     indefinitely without problem. While streaming replication is in
14891     progress WAL records will continue to be received, which will
14892     eventually fill available disk space, depending upon the duration of
14893     the pause, the rate of WAL generation and available disk space.
14894    </para>
14895
14896   </sect2>
14897
14898   <sect2 id="functions-snapshot-synchronization">
14899    <title>Snapshot Synchronization Functions</title>
14900
14901    <indexterm>
14902      <primary>pg_export_snapshot</primary>
14903    </indexterm>
14904
14905    <para>
14906     <productname>PostgreSQL</> allows database sessions to synchronize their
14907     snapshots. A <firstterm>snapshot</> determines which data is visible to the
14908     transaction that is using the snapshot. Synchronized snapshots are
14909     necessary when two or more sessions need to see identical content in the
14910     database. If two sessions just start their transactions independently,
14911     there is always a possibility that some third transaction commits
14912     between the executions of the two <command>START TRANSACTION</> commands,
14913     so that one session sees the effects of that transaction and the other
14914     does not.
14915    </para>
14916
14917    <para>
14918     To solve this problem, <productname>PostgreSQL</> allows a transaction to
14919     <firstterm>export</> the snapshot it is using.  As long as the exporting
14920     transaction remains open, other transactions can <firstterm>import</> its
14921     snapshot, and thereby be guaranteed that they see exactly the same view
14922     of the database that the first transaction sees.  But note that any
14923     database changes made by any one of these transactions remain invisible
14924     to the other transactions, as is usual for changes made by uncommitted
14925     transactions.  So the transactions are synchronized with respect to
14926     pre-existing data, but act normally for changes they make themselves.
14927    </para>
14928
14929    <para>
14930     Snapshots are exported with the <function>pg_export_snapshot</> function,
14931     shown in <xref linkend="functions-snapshot-synchronization-table">, and
14932     imported with the <xref linkend="sql-set-transaction"> command.
14933    </para>
14934
14935    <table id="functions-snapshot-synchronization-table">
14936     <title>Snapshot Synchronization Functions</title>
14937     <tgroup cols="3">
14938      <thead>
14939       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14940       </row>
14941      </thead>
14942
14943      <tbody>
14944       <row>
14945        <entry>
14946         <literal><function>pg_export_snapshot()</function></literal>
14947        </entry>
14948        <entry><type>text</type></entry>
14949        <entry>Save the current snapshot and return its identifier</entry>
14950       </row>
14951      </tbody>
14952     </tgroup>
14953    </table>
14954
14955    <para>
14956     The function <function>pg_export_snapshot</> saves the current snapshot
14957     and returns a <type>text</> string identifying the snapshot.  This string
14958     must be passed (outside the database) to clients that want to import the
14959     snapshot.  The snapshot is available for import only until the end of the
14960     transaction that exported it.  A transaction can export more than one
14961     snapshot, if needed.  Note that doing so is only useful in <literal>READ
14962     COMMITTED</> transactions, since in <literal>REPEATABLE READ</> and
14963     higher isolation levels, transactions use the same snapshot throughout
14964     their lifetime.  Once a transaction has exported any snapshots, it cannot
14965     be prepared with <xref linkend="sql-prepare-transaction">.
14966    </para>
14967
14968    <para>
14969     See  <xref linkend="sql-set-transaction"> for details of how to use an
14970     exported snapshot.
14971    </para>
14972   </sect2>
14973
14974   <sect2 id="functions-admin-dbobject">
14975    <title>Database Object Management Functions</title>
14976
14977    <para>
14978     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
14979     the disk space usage of database objects.
14980    </para>
14981
14982    <indexterm>
14983     <primary>pg_column_size</primary>
14984    </indexterm>
14985    <indexterm>
14986     <primary>pg_database_size</primary>
14987    </indexterm>
14988    <indexterm>
14989     <primary>pg_indexes_size</primary>
14990    </indexterm>
14991    <indexterm>
14992     <primary>pg_relation_size</primary>
14993    </indexterm>
14994    <indexterm>
14995     <primary>pg_size_pretty</primary>
14996    </indexterm>
14997    <indexterm>
14998     <primary>pg_table_size</primary>
14999    </indexterm>
15000    <indexterm>
15001     <primary>pg_tablespace_size</primary>
15002    </indexterm>
15003    <indexterm>
15004     <primary>pg_total_relation_size</primary>
15005    </indexterm>
15006
15007    <table id="functions-admin-dbsize">
15008     <title>Database Object Size Functions</title>
15009     <tgroup cols="3">
15010      <thead>
15011       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15012       </row>
15013      </thead>
15014
15015      <tbody>
15016       <row>
15017        <entry><literal><function>pg_column_size(<type>any</type>)</function></literal></entry>
15018        <entry><type>int</type></entry>
15019        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
15020       </row>
15021       <row>
15022        <entry>
15023         <literal><function>pg_database_size(<type>oid</type>)</function></literal>
15024         </entry>
15025        <entry><type>bigint</type></entry>
15026        <entry>Disk space used by the database with the specified OID</entry>
15027       </row>
15028       <row>
15029        <entry>
15030         <literal><function>pg_database_size(<type>name</type>)</function></literal>
15031         </entry>
15032        <entry><type>bigint</type></entry>
15033        <entry>Disk space used by the database with the specified name</entry>
15034       </row>
15035       <row>
15036        <entry>
15037         <literal><function>pg_indexes_size(<type>regclass</type>)</function></literal>
15038         </entry>
15039        <entry><type>bigint</type></entry>
15040        <entry>
15041         Total disk space used by indexes attached to the specified table
15042        </entry>
15043       </row>
15044       <row>
15045        <entry>
15046         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</function></literal>
15047         </entry>
15048        <entry><type>bigint</type></entry>
15049        <entry>
15050         Disk space used by the specified fork (<literal>'main'</literal>,
15051         <literal>'fsm'</literal> or <literal>'vm'</>)
15052         of the specified table or index
15053        </entry>
15054       </row>
15055       <row>
15056        <entry>
15057         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
15058         </entry>
15059        <entry><type>bigint</type></entry>
15060        <entry>
15061         Shorthand for <literal>pg_relation_size(..., 'main')</literal>
15062        </entry>
15063       </row>
15064       <row>
15065        <entry>
15066         <literal><function>pg_size_pretty(<type>bigint</type>)</function></literal>
15067         </entry>
15068        <entry><type>text</type></entry>
15069        <entry>
15070          Converts a size in bytes expressed as a 64-bit integer into a
15071          human-readable format with size units
15072        </entry>
15073       </row>
15074       <row>
15075        <entry>
15076         <literal><function>pg_size_pretty(<type>numeric</type>)</function></literal>
15077         </entry>
15078        <entry><type>text</type></entry>
15079        <entry>
15080          Converts a size in bytes expressed as a numeric value into a
15081          human-readable format with size units
15082        </entry>
15083       </row>
15084       <row>
15085        <entry>
15086         <literal><function>pg_table_size(<type>regclass</type>)</function></literal>
15087         </entry>
15088        <entry><type>bigint</type></entry>
15089        <entry>
15090         Disk space used by the specified table, excluding indexes
15091         (but including TOAST, free space map, and visibility map)
15092        </entry>
15093       </row>
15094       <row>
15095        <entry>
15096         <literal><function>pg_tablespace_size(<type>oid</type>)</function></literal>
15097         </entry>
15098        <entry><type>bigint</type></entry>
15099        <entry>Disk space used by the tablespace with the specified OID</entry>
15100       </row>
15101       <row>
15102        <entry>
15103         <literal><function>pg_tablespace_size(<type>name</type>)</function></literal>
15104         </entry>
15105        <entry><type>bigint</type></entry>
15106        <entry>Disk space used by the tablespace with the specified name</entry>
15107       </row>
15108       <row>
15109        <entry>
15110         <literal><function>pg_total_relation_size(<type>regclass</type>)</function></literal>
15111         </entry>
15112        <entry><type>bigint</type></entry>
15113        <entry>
15114         Total disk space used by the specified table,
15115         including all indexes and <acronym>TOAST</> data
15116        </entry>
15117       </row>
15118      </tbody>
15119     </tgroup>
15120    </table>
15121
15122    <para>
15123     <function>pg_column_size</> shows the space used to store any individual
15124     data value.
15125    </para>
15126
15127    <para>
15128     <function>pg_total_relation_size</> accepts the OID or name of a
15129     table or toast table, and returns the total on-disk space used for
15130     that table, including all associated indexes.  This function is
15131     equivalent to <function>pg_table_size</function>
15132     <literal>+</> <function>pg_indexes_size</function>.
15133    </para>
15134
15135    <para>
15136     <function>pg_table_size</> accepts the OID or name of a table and
15137     returns the disk space needed for that table, exclusive of indexes.
15138     (TOAST space, free space map, and visibility map are included.)
15139    </para>
15140
15141    <para>
15142     <function>pg_indexes_size</> accepts the OID or name of a table and
15143     returns the total disk space used by all the indexes attached to that
15144     table.
15145    </para>
15146
15147    <para>
15148     <function>pg_database_size</function> and <function>pg_tablespace_size</>
15149     accept the OID or name of a database or tablespace, and return the total
15150     disk space used therein.
15151    </para>
15152
15153    <para>
15154     <function>pg_relation_size</> accepts the OID or name of a table, index or
15155     toast table, and returns the on-disk size in bytes. Specifying
15156     <literal>'main'</literal> or leaving out the second argument returns the
15157     size of the main data fork of the relation. Specifying
15158     <literal>'fsm'</literal> returns the size of the
15159     Free Space Map (see <xref linkend="storage-fsm">) associated with the
15160     relation. Specifying <literal>'vm'</literal> returns the size of the
15161     Visibility Map (see <xref linkend="storage-vm">) associated with the
15162     relation.  Note that this function shows the size of only one fork;
15163     for most purposes it is more convenient to use the higher-level
15164     functions <function>pg_total_relation_size</> or
15165     <function>pg_table_size</>.
15166    </para>
15167
15168    <para>
15169     <function>pg_size_pretty</> can be used to format the result of one of
15170     the other functions in a human-readable way, using kB, MB, GB or TB as
15171     appropriate.
15172    </para>
15173
15174    <para>
15175     The functions above that operate on tables or indexes accept a
15176     <type>regclass</> argument, which is simply the OID of the table or index
15177     in the <structname>pg_class</> system catalog.  You do not have to look up
15178     the OID by hand, however, since the <type>regclass</> data type's input
15179     converter will do the work for you.  Just write the table name enclosed in
15180     single quotes so that it looks like a literal constant.  For compatibility
15181     with the handling of ordinary <acronym>SQL</acronym> names, the string
15182     will be converted to lower case unless it contains double quotes around
15183     the table name.
15184    </para>
15185
15186    <para>
15187     If an OID that does not represent an existing object is passed as
15188     argument to one of the above functions, NULL is returned.
15189    </para>
15190
15191    <para>
15192     The functions shown in <xref linkend="functions-admin-dblocation"> assist
15193     in identifying the specific disk files associated with database objects.
15194    </para>
15195
15196    <indexterm>
15197     <primary>pg_relation_filenode</primary>
15198    </indexterm>
15199    <indexterm>
15200     <primary>pg_relation_filepath</primary>
15201    </indexterm>
15202
15203    <table id="functions-admin-dblocation">
15204     <title>Database Object Location Functions</title>
15205     <tgroup cols="3">
15206      <thead>
15207       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15208       </row>
15209      </thead>
15210
15211      <tbody>
15212       <row>
15213        <entry>
15214         <literal><function>pg_relation_filenode(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
15215         </entry>
15216        <entry><type>oid</type></entry>
15217        <entry>
15218         Filenode number of the specified relation
15219        </entry>
15220       </row>
15221       <row>
15222        <entry>
15223         <literal><function>pg_relation_filepath(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
15224         </entry>
15225        <entry><type>text</type></entry>
15226        <entry>
15227         File path name of the specified relation
15228        </entry>
15229       </row>
15230      </tbody>
15231     </tgroup>
15232    </table>
15233
15234    <para>
15235     <function>pg_relation_filenode</> accepts the OID or name of a table,
15236     index, sequence, or toast table, and returns the <quote>filenode</> number
15237     currently assigned to it.  The filenode is the base component of the file
15238     name(s) used for the relation (see <xref linkend="storage-file-layout">
15239     for more information).  For most tables the result is the same as
15240     <structname>pg_class</>.<structfield>relfilenode</>, but for certain
15241     system catalogs <structfield>relfilenode</> is zero and this function must
15242     be used to get the correct value.  The function returns NULL if passed
15243     a relation that does not have storage, such as a view.
15244    </para>
15245
15246    <para>
15247     <function>pg_relation_filepath</> is similar to
15248     <function>pg_relation_filenode</>, but it returns the entire file path name
15249     (relative to the database cluster's data directory <varname>PGDATA</>) of
15250     the relation.
15251    </para>
15252
15253   </sect2>
15254
15255   <sect2 id="functions-admin-genfile">
15256    <title>Generic File Access Functions</title>
15257
15258    <para>
15259     The functions shown in <xref
15260     linkend="functions-admin-genfile-table"> provide native access to
15261     files on the machine hosting the server. Only files within the
15262     database cluster directory and the <varname>log_directory</> can be
15263     accessed.  Use a relative path for files in the cluster directory,
15264     and a path matching the <varname>log_directory</> configuration setting
15265     for log files.  Use of these functions is restricted to superusers.
15266    </para>
15267
15268    <table id="functions-admin-genfile-table">
15269     <title>Generic File Access Functions</title>
15270     <tgroup cols="3">
15271      <thead>
15272       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15273       </row>
15274      </thead>
15275
15276      <tbody>
15277       <row>
15278        <entry>
15279         <literal><function>pg_ls_dir(<parameter>dirname</> <type>text</>)</function></literal>
15280        </entry>
15281        <entry><type>setof text</type></entry>
15282        <entry>List the contents of a directory</entry>
15283       </row>
15284       <row>
15285        <entry>
15286         <literal><function>pg_read_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
15287        </entry>
15288        <entry><type>text</type></entry>
15289        <entry>Return the contents of a text file</entry>
15290       </row>
15291       <row>
15292        <entry>
15293         <literal><function>pg_read_binary_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
15294        </entry>
15295        <entry><type>bytea</type></entry>
15296        <entry>Return the contents of a file</entry>
15297       </row>
15298       <row>
15299        <entry>
15300         <literal><function>pg_stat_file(<parameter>filename</> <type>text</>)</function></literal>
15301        </entry>
15302        <entry><type>record</type></entry>
15303        <entry>Return information about a file</entry>
15304       </row>
15305      </tbody>
15306     </tgroup>
15307    </table>
15308
15309    <indexterm>
15310     <primary>pg_ls_dir</primary>
15311    </indexterm>
15312    <para>
15313     <function>pg_ls_dir</> returns all the names in the specified
15314     directory, except the special entries <quote><literal>.</></> and
15315     <quote><literal>..</></>.
15316    </para>
15317
15318    <indexterm>
15319     <primary>pg_read_file</primary>
15320    </indexterm>
15321    <para>
15322     <function>pg_read_file</> returns part of a text file, starting
15323     at the given <parameter>offset</>, returning at most <parameter>length</>
15324     bytes (less if the end of file is reached first).  If <parameter>offset</>
15325     is negative, it is relative to the end of the file.
15326     If <parameter>offset</> and <parameter>length</> are omitted, the entire
15327     file is returned.  The bytes read from the file are interpreted as a string
15328     in the server encoding; an error is thrown if they are not valid in that
15329     encoding.
15330    </para>
15331
15332    <indexterm>
15333     <primary>pg_read_binary_file</primary>
15334    </indexterm>
15335    <para>
15336     <function>pg_read_binary_file</> is similar to
15337     <function>pg_read_file</>, except that the result is a <type>bytea</type> value;
15338     accordingly, no encoding checks are performed.
15339     In combination with the <function>convert_from</> function, this function
15340     can be used to read a file in a specified encoding:
15341 <programlisting>
15342 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
15343 </programlisting>
15344    </para>
15345
15346    <indexterm>
15347     <primary>pg_stat_file</primary>
15348    </indexterm>
15349    <para>
15350     <function>pg_stat_file</> returns a record containing the file
15351     size, last accessed time stamp, last modified time stamp,
15352     last file status change time stamp (Unix platforms only),
15353     file creation time stamp (Windows only), and a <type>boolean</type>
15354     indicating if it is a directory.  Typical usages include:
15355 <programlisting>
15356 SELECT * FROM pg_stat_file('filename');
15357 SELECT (pg_stat_file('filename')).modification;
15358 </programlisting>
15359    </para>
15360
15361   </sect2>
15362
15363   <sect2 id="functions-advisory-locks">
15364    <title>Advisory Lock Functions</title>
15365
15366    <para>
15367     The functions shown in <xref linkend="functions-advisory-locks-table">
15368     manage advisory locks.  For details about proper use of these functions,
15369     see <xref linkend="advisory-locks">.
15370    </para>
15371
15372    <table id="functions-advisory-locks-table">
15373     <title>Advisory Lock Functions</title>
15374     <tgroup cols="3">
15375      <thead>
15376       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
15377       </row>
15378      </thead>
15379
15380      <tbody>
15381       <row>
15382        <entry>
15383         <literal><function>pg_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
15384        </entry>
15385        <entry><type>void</type></entry>
15386        <entry>Obtain exclusive session level advisory lock</entry>
15387       </row>
15388       <row>
15389        <entry>
15390         <literal><function>pg_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15391        </entry>
15392        <entry><type>void</type></entry>
15393        <entry>Obtain exclusive session level advisory lock</entry>
15394       </row>
15395       <row>
15396        <entry>
15397         <literal><function>pg_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
15398        </entry>
15399        <entry><type>void</type></entry>
15400        <entry>Obtain shared session level advisory lock</entry>
15401       </row>
15402       <row>
15403        <entry>
15404         <literal><function>pg_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15405        </entry>
15406        <entry><type>void</type></entry>
15407        <entry>Obtain shared session level advisory lock</entry>
15408       </row>
15409       <row>
15410        <entry>
15411         <literal><function>pg_advisory_unlock(<parameter>key</> <type>bigint</>)</function></literal>
15412        </entry>
15413        <entry><type>boolean</type></entry>
15414        <entry>Release an exclusive session level advisory lock</entry>
15415       </row>
15416       <row>
15417        <entry>
15418         <literal><function>pg_advisory_unlock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15419        </entry>
15420        <entry><type>boolean</type></entry>
15421        <entry>Release an exclusive session level advisory lock</entry>
15422       </row>
15423       <row>
15424        <entry>
15425         <literal><function>pg_advisory_unlock_all()</function></literal>
15426        </entry>
15427        <entry><type>void</type></entry>
15428        <entry>Release all session level advisory locks held by the current session</entry>
15429       </row>
15430       <row>
15431        <entry>
15432         <literal><function>pg_advisory_unlock_shared(<parameter>key</> <type>bigint</>)</function></literal>
15433        </entry>
15434        <entry><type>boolean</type></entry>
15435        <entry>Release a shared session level advisory lock</entry>
15436       </row>
15437       <row>
15438        <entry>
15439         <literal><function>pg_advisory_unlock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15440        </entry>
15441        <entry><type>boolean</type></entry>
15442        <entry>Release a shared session level advisory lock</entry>
15443       </row>
15444       <row>
15445        <entry>
15446         <literal><function>pg_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
15447        </entry>
15448        <entry><type>void</type></entry>
15449        <entry>Obtain exclusive transaction level advisory lock</entry>
15450       </row>
15451       <row>
15452        <entry>
15453         <literal><function>pg_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15454        </entry>
15455        <entry><type>void</type></entry>
15456        <entry>Obtain exclusive transaction level advisory lock</entry>
15457       </row>
15458       <row>
15459        <entry>
15460         <literal><function>pg_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
15461        </entry>
15462        <entry><type>void</type></entry>
15463        <entry>Obtain shared transaction level advisory lock</entry>
15464       </row>
15465       <row>
15466        <entry>
15467         <literal><function>pg_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15468        </entry>
15469        <entry><type>void</type></entry>
15470        <entry>Obtain shared transaction level advisory lock</entry>
15471       </row>
15472       <row>
15473        <entry>
15474         <literal><function>pg_try_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
15475        </entry>
15476        <entry><type>boolean</type></entry>
15477        <entry>Obtain exclusive session level advisory lock if available</entry>
15478       </row>
15479       <row>
15480        <entry>
15481         <literal><function>pg_try_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15482        </entry>
15483        <entry><type>boolean</type></entry>
15484        <entry>Obtain exclusive session level advisory lock if available</entry>
15485       </row>
15486       <row>
15487        <entry>
15488         <literal><function>pg_try_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
15489        </entry>
15490        <entry><type>boolean</type></entry>
15491        <entry>Obtain shared session level advisory lock if available</entry>
15492       </row>
15493       <row>
15494        <entry>
15495         <literal><function>pg_try_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15496        </entry>
15497        <entry><type>boolean</type></entry>
15498        <entry>Obtain shared session level advisory lock if available</entry>
15499       </row>
15500       <row>
15501        <entry>
15502         <literal><function>pg_try_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
15503        </entry>
15504        <entry><type>boolean</type></entry>
15505        <entry>Obtain exclusive transaction level advisory lock if available</entry>
15506       </row>
15507       <row>
15508        <entry>
15509         <literal><function>pg_try_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15510        </entry>
15511        <entry><type>boolean</type></entry>
15512        <entry>Obtain exclusive transaction level advisory lock if available</entry>
15513       </row>
15514       <row>
15515        <entry>
15516         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
15517        </entry>
15518        <entry><type>boolean</type></entry>
15519        <entry>Obtain shared transaction level advisory lock if available</entry>
15520       </row>
15521       <row>
15522        <entry>
15523         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
15524        </entry>
15525        <entry><type>boolean</type></entry>
15526        <entry>Obtain shared transaction level advisory lock if available</entry>
15527       </row>
15528      </tbody>
15529     </tgroup>
15530    </table>
15531
15532    <indexterm>
15533     <primary>pg_advisory_lock</primary>
15534    </indexterm>
15535    <para>
15536     <function>pg_advisory_lock</> locks an application-defined resource,
15537     which can be identified either by a single 64-bit key value or two
15538     32-bit key values (note that these two key spaces do not overlap).
15539     If another session already holds a lock on the same resource identifier,
15540     this function will wait until the resource becomes available.  The lock
15541     is exclusive.  Multiple lock requests stack, so that if the same resource
15542     is locked three times it must then be unlocked three times to be
15543     released for other sessions' use.
15544    </para>
15545
15546    <indexterm>
15547     <primary>pg_advisory_lock_shared</primary>
15548    </indexterm>
15549    <para>
15550     <function>pg_advisory_lock_shared</> works the same as
15551     <function>pg_advisory_lock</>,
15552     except the lock can be shared with other sessions requesting shared locks.
15553     Only would-be exclusive lockers are locked out.
15554    </para>
15555
15556    <indexterm>
15557     <primary>pg_try_advisory_lock</primary>
15558    </indexterm>
15559    <para>
15560     <function>pg_try_advisory_lock</> is similar to
15561     <function>pg_advisory_lock</>, except the function will not wait for the
15562     lock to become available.  It will either obtain the lock immediately and
15563     return <literal>true</>, or return <literal>false</> if the lock cannot be
15564     acquired immediately.
15565    </para>
15566
15567    <indexterm>
15568     <primary>pg_try_advisory_lock_shared</primary>
15569    </indexterm>
15570    <para>
15571     <function>pg_try_advisory_lock_shared</> works the same as
15572     <function>pg_try_advisory_lock</>, except it attempts to acquire
15573     a shared rather than an exclusive lock.
15574    </para>
15575
15576    <indexterm>
15577     <primary>pg_advisory_unlock</primary>
15578    </indexterm>
15579    <para>
15580     <function>pg_advisory_unlock</> will release a previously-acquired
15581     exclusive session level advisory lock.  It
15582     returns <literal>true</> if the lock is successfully released.
15583     If the lock was not held, it will return <literal>false</>,
15584     and in addition, an SQL warning will be reported by the server.
15585    </para>
15586
15587    <indexterm>
15588     <primary>pg_advisory_unlock_shared</primary>
15589    </indexterm>
15590    <para>
15591     <function>pg_advisory_unlock_shared</> works the same as
15592     <function>pg_advisory_unlock</>,
15593     except it releases a shared session level advisory lock.
15594    </para>
15595
15596    <indexterm>
15597     <primary>pg_advisory_unlock_all</primary>
15598    </indexterm>
15599    <para>
15600     <function>pg_advisory_unlock_all</> will release all session level advisory
15601     locks held by the current session.  (This function is implicitly invoked
15602     at session end, even if the client disconnects ungracefully.)
15603    </para>
15604
15605    <indexterm>
15606     <primary>pg_advisory_xact_lock</primary>
15607    </indexterm>
15608    <para>
15609     <function>pg_advisory_xact_lock</> works the same as
15610     <function>pg_advisory_lock</>, except the lock is automatically released
15611     at the end of the current transaction and cannot be released explicitly.
15612    </para>
15613
15614    <indexterm>
15615     <primary>pg_advisory_xact_lock_shared</primary>
15616    </indexterm>
15617    <para>
15618     <function>pg_advisory_xact_lock_shared</> works the same as
15619     <function>pg_advisory_lock_shared</>, except the lock is automatically released
15620     at the end of the current transaction and cannot be released explicitly.
15621    </para>
15622
15623    <indexterm>
15624     <primary>pg_try_advisory_xact_lock</primary>
15625    </indexterm>
15626    <para>
15627     <function>pg_try_advisory_xact_lock</> works the same as
15628     <function>pg_try_advisory_lock</>, except the lock, if acquired,
15629     is automatically released at the end of the current transaction and
15630     cannot be released explicitly.
15631    </para>
15632
15633    <indexterm>
15634     <primary>pg_try_advisory_xact_lock_shared</primary>
15635    </indexterm>
15636    <para>
15637     <function>pg_try_advisory_xact_lock_shared</> works the same as
15638     <function>pg_try_advisory_lock_shared</>, except the lock, if acquired,
15639     is automatically released at the end of the current transaction and
15640     cannot be released explicitly.
15641    </para>
15642
15643   </sect2>
15644
15645   </sect1>
15646
15647   <sect1 id="functions-trigger">
15648    <title>Trigger Functions</title>
15649
15650    <indexterm>
15651      <primary>suppress_redundant_updates_trigger</primary>
15652    </indexterm>
15653
15654    <para>
15655       Currently <productname>PostgreSQL</> provides one built in trigger
15656       function, <function>suppress_redundant_updates_trigger</>,
15657       which will prevent any update
15658       that does not actually change the data in the row from taking place, in
15659       contrast to the normal behavior which always performs the update
15660       regardless of whether or not the data has changed. (This normal behavior
15661       makes updates run faster, since no checking is required, and is also
15662       useful in certain cases.)
15663     </para>
15664
15665     <para>
15666       Ideally, you should normally avoid running updates that don't actually
15667       change the data in the record. Redundant updates can cost considerable
15668       unnecessary time, especially if there are lots of indexes to alter,
15669       and space in dead rows that will eventually have to be vacuumed.
15670       However, detecting such situations in client code is not
15671       always easy, or even possible, and writing expressions to detect
15672       them can be error-prone. An alternative is to use
15673       <function>suppress_redundant_updates_trigger</>, which will skip
15674       updates that don't change the data. You should use this with care,
15675       however. The trigger takes a small but non-trivial time for each record,
15676       so if most of the records affected by an update are actually changed,
15677       use of this trigger will actually make the update run slower.
15678     </para>
15679
15680     <para>
15681       The <function>suppress_redundant_updates_trigger</> function can be
15682       added to a table like this:
15683 <programlisting>
15684 CREATE TRIGGER z_min_update
15685 BEFORE UPDATE ON tablename
15686 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
15687 </programlisting>
15688       In most cases, you would want to fire this trigger last for each row.
15689       Bearing in mind that triggers fire in name order, you would then
15690       choose a trigger name that comes after the name of any other trigger
15691       you might have on the table.
15692     </para>
15693     <para>
15694        For more information about creating triggers, see
15695         <xref linkend="SQL-CREATETRIGGER">.
15696     </para>
15697   </sect1>
15698 </chapter>