]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
Change wording for COALESCE docs to use "otherwise".
[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.  When this behavior is not suitable,
368     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 all arguments. NULL arguments are ignored.
1398        </entry>
1399        <entry><literal>concat('abcde', 2, NULL, 22)</literal></entry>
1400        <entry><literal>abcde222</literal></entry>
1401       </row>
1402
1403       <row>
1404        <entry>
1405         <indexterm>
1406          <primary>concat_ws</primary>
1407         </indexterm>
1408         <literal><function>concat_ws(<parameter>sep</parameter> <type>text</type>,
1409         <parameter>str</parameter> <type>"any"</type>
1410         [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
1411        </entry>
1412        <entry><type>text</type></entry>
1413        <entry>
1414         Concatenate all but first arguments with separators. The first
1415         parameter is used as a separator. NULL arguments are ignored.
1416        </entry>
1417        <entry><literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal></entry>
1418        <entry><literal>abcde,2,22</literal></entry>
1419       </row>
1420
1421       <row>
1422        <entry>
1423         <indexterm>
1424          <primary>convert</primary>
1425         </indexterm>
1426         <literal><function>convert(<parameter>string</parameter> <type>bytea</type>,
1427         <parameter>src_encoding</parameter> <type>name</type>,
1428         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1429        </entry>
1430        <entry><type>bytea</type></entry>
1431        <entry>
1432         Convert string to <parameter>dest_encoding</parameter>.  The
1433         original encoding is specified by
1434         <parameter>src_encoding</parameter>. The
1435         <parameter>string</parameter> must be valid in this encoding.
1436         Conversions can be defined by <command>CREATE CONVERSION</command>.
1437         Also there are some predefined conversions. See <xref
1438         linkend="conversion-names"> for available conversions.
1439        </entry>
1440        <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1441        <entry><literal>text_in_utf8</literal> represented in Latin-1
1442        encoding (ISO 8859-1)</entry>
1443       </row>
1444
1445       <row>
1446        <entry>
1447         <indexterm>
1448          <primary>convert_from</primary>
1449         </indexterm>
1450         <literal><function>convert_from(<parameter>string</parameter> <type>bytea</type>,
1451         <parameter>src_encoding</parameter> <type>name</type>)</function></literal>
1452        </entry>
1453        <entry><type>text</type></entry>
1454        <entry>
1455         Convert string to the database encoding.  The original encoding
1456         is specified by <parameter>src_encoding</parameter>. The
1457         <parameter>string</parameter> must be valid in this encoding.
1458        </entry>
1459        <entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
1460        <entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
1461       </row>
1462
1463       <row>
1464        <entry>
1465         <indexterm>
1466          <primary>convert_to</primary>
1467         </indexterm>
1468         <literal><function>convert_to(<parameter>string</parameter> <type>text</type>,
1469         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1470        </entry>
1471        <entry><type>bytea</type></entry>
1472        <entry>
1473         Convert string to <parameter>dest_encoding</parameter>.
1474        </entry>
1475        <entry><literal>convert_to('some text', 'UTF8')</literal></entry>
1476        <entry><literal>some text</literal> represented in the UTF8 encoding</entry>
1477       </row>
1478
1479       <row>
1480        <entry>
1481         <indexterm>
1482          <primary>decode</primary>
1483         </indexterm>
1484         <literal><function>decode(<parameter>string</parameter> <type>text</type>,
1485         <parameter>format</parameter> <type>text</type>)</function></literal>
1486        </entry>
1487        <entry><type>bytea</type></entry>
1488        <entry>
1489         Decode binary data from textual representation in <parameter>string</>.
1490         Options for <parameter>format</> are same as in <function>encode</>.
1491        </entry>
1492        <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
1493        <entry><literal>\x3132330001</literal></entry>
1494       </row>
1495
1496       <row>
1497        <entry>
1498         <indexterm>
1499          <primary>encode</primary>
1500         </indexterm>
1501         <literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
1502         <parameter>format</parameter> <type>text</type>)</function></literal>
1503        </entry>
1504        <entry><type>text</type></entry>
1505        <entry>
1506         Encode binary data into a textual representation.  Supported
1507         formats are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
1508         <literal>escape</> merely outputs null bytes as <literal>\000</> and
1509         doubles backslashes.
1510        </entry>
1511        <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1512        <entry><literal>MTIzAAE=</literal></entry>
1513       </row>
1514
1515       <row>
1516        <entry id="format">
1517         <indexterm>
1518          <primary>format</primary>
1519         </indexterm>
1520         <literal><function>format</function>(<parameter>formatstr</parameter> <type>text</type>
1521         [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</literal>
1522        </entry>
1523        <entry><type>text</type></entry>
1524        <entry>
1525          Format a string.  This function is similar to the C function
1526          <function>sprintf</>; but only the following conversion specifications
1527          are recognized: <literal>%s</literal> interpolates the corresponding
1528          argument as a string; <literal>%I</literal> escapes its argument as
1529          an SQL identifier; <literal>%L</literal> escapes its argument as an
1530          SQL literal; <literal>%%</literal> outputs a literal <literal>%</>.
1531          A conversion can reference an explicit parameter position by preceding
1532          the conversion specifier with <literal><replaceable>n</>$</>, where
1533          <replaceable>n</replaceable> is the argument position.
1534          See also <xref linkend="plpgsql-quote-literal-example">.
1535        </entry>
1536        <entry><literal>format('Hello %s, %1$s', 'World')</literal></entry>
1537        <entry><literal>Hello World, World</literal></entry>
1538       </row>
1539
1540       <row>
1541        <entry>
1542         <indexterm>
1543          <primary>initcap</primary>
1544         </indexterm>
1545         <literal><function>initcap(<parameter>string</parameter>)</function></literal>
1546        </entry>
1547        <entry><type>text</type></entry>
1548        <entry>
1549         Convert the first letter of each word to upper case and the
1550         rest to lower case. Words are sequences of alphanumeric
1551         characters separated by non-alphanumeric characters.
1552        </entry>
1553        <entry><literal>initcap('hi THOMAS')</literal></entry>
1554        <entry><literal>Hi Thomas</literal></entry>
1555       </row>
1556
1557       <row>
1558        <entry>
1559         <indexterm>
1560          <primary>left</primary>
1561         </indexterm>
1562         <literal><function>left(<parameter>str</parameter> <type>text</type>,
1563         <parameter>n</parameter> <type>int</type>)</function></literal>
1564        </entry>
1565        <entry><type>text</type></entry>
1566        <entry>
1567         Return first <replaceable>n</> characters in the string. When <replaceable>n</>
1568         is negative, return all but last |<replaceable>n</>| characters.
1569         </entry>
1570        <entry><literal>left('abcde', 2)</literal></entry>
1571        <entry><literal>ab</literal></entry>
1572       </row>
1573
1574       <row>
1575        <entry>
1576         <indexterm>
1577          <primary>length</primary>
1578         </indexterm>
1579         <literal><function>length(<parameter>string</parameter>)</function></literal>
1580        </entry>
1581        <entry><type>int</type></entry>
1582        <entry>
1583         Number of characters in <parameter>string</parameter>
1584        </entry>
1585        <entry><literal>length('jose')</literal></entry>
1586        <entry><literal>4</literal></entry>
1587       </row>
1588
1589       <row>
1590        <entry><literal><function>length(<parameter>string</parameter><type>bytea</type>,
1591         <parameter>encoding</parameter> <type>name</type> )</function></literal></entry>
1592        <entry><type>int</type></entry>
1593        <entry>
1594         Number of characters in <parameter>string</parameter> in the given
1595         <parameter>encoding</parameter>. The <parameter>string</parameter>
1596         must be valid in this encoding.
1597        </entry>
1598        <entry><literal>length('jose', 'UTF8')</literal></entry>
1599        <entry><literal>4</literal></entry>
1600       </row>
1601
1602       <row>
1603        <entry>
1604         <indexterm>
1605          <primary>lpad</primary>
1606         </indexterm>
1607         <literal><function>lpad(<parameter>string</parameter> <type>text</type>,
1608         <parameter>length</parameter> <type>int</type>
1609         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1610        </entry>
1611        <entry><type>text</type></entry>
1612        <entry>
1613         Fill up the <parameter>string</parameter> to length
1614         <parameter>length</parameter> by prepending the characters
1615         <parameter>fill</parameter> (a space by default).  If the
1616         <parameter>string</parameter> is already longer than
1617         <parameter>length</parameter> then it is truncated (on the
1618         right).
1619        </entry>
1620        <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1621        <entry><literal>xyxhi</literal></entry>
1622       </row>
1623
1624       <row>
1625        <entry>
1626         <indexterm>
1627          <primary>ltrim</primary>
1628         </indexterm>
1629         <literal><function>ltrim(<parameter>string</parameter> <type>text</type>
1630         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1631        </entry>
1632        <entry><type>text</type></entry>
1633        <entry>
1634         Remove the longest string containing only characters from
1635         <parameter>characters</parameter> (a space by default) from the start of
1636         <parameter>string</parameter>
1637        </entry>
1638        <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
1639        <entry><literal>trim</literal></entry>
1640       </row>
1641
1642       <row>
1643        <entry>
1644         <indexterm>
1645          <primary>md5</primary>
1646         </indexterm>
1647         <literal><function>md5(<parameter>string</parameter>)</function></literal>
1648        </entry>
1649        <entry><type>text</type></entry>
1650        <entry>
1651         Calculates the MD5 hash of <parameter>string</parameter>,
1652         returning the result in hexadecimal
1653        </entry>
1654        <entry><literal>md5('abc')</literal></entry>
1655        <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1656       </row>
1657
1658       <row>
1659        <entry>
1660         <indexterm>
1661          <primary>pg_client_encoding</primary>
1662         </indexterm>
1663         <literal><function>pg_client_encoding()</function></literal>
1664        </entry>
1665        <entry><type>name</type></entry>
1666        <entry>
1667         Current client encoding name
1668        </entry>
1669        <entry><literal>pg_client_encoding()</literal></entry>
1670        <entry><literal>SQL_ASCII</literal></entry>
1671       </row>
1672
1673       <row>
1674        <entry>
1675         <indexterm>
1676          <primary>quote_ident</primary>
1677         </indexterm>
1678         <literal><function>quote_ident(<parameter>string</parameter> <type>text</type>)</function></literal>
1679        </entry>
1680        <entry><type>text</type></entry>
1681        <entry>
1682         Return the given string suitably quoted to be used as an identifier
1683         in an <acronym>SQL</acronym> statement string.
1684         Quotes are added only if necessary (i.e., if the string contains
1685         non-identifier characters or would be case-folded).
1686         Embedded quotes are properly doubled.
1687         See also <xref linkend="plpgsql-quote-literal-example">.
1688        </entry>
1689        <entry><literal>quote_ident('Foo bar')</literal></entry>
1690        <entry><literal>"Foo bar"</literal></entry>
1691       </row>
1692
1693       <row>
1694        <entry>
1695         <indexterm>
1696          <primary>quote_literal</primary>
1697         </indexterm>
1698         <literal><function>quote_literal(<parameter>string</parameter> <type>text</type>)</function></literal>
1699        </entry>
1700        <entry><type>text</type></entry>
1701        <entry>
1702         Return the given string suitably quoted to be used as a string literal
1703         in an <acronym>SQL</acronym> statement string.
1704         Embedded single-quotes and backslashes are properly doubled.
1705         Note that <function>quote_literal</function> returns null on null
1706         input; if the argument might be null,
1707         <function>quote_nullable</function> is often more suitable.
1708         See also <xref linkend="plpgsql-quote-literal-example">.
1709        </entry>
1710        <entry><literal>quote_literal(E'O\'Reilly')</literal></entry>
1711        <entry><literal>'O''Reilly'</literal></entry>
1712       </row>
1713
1714       <row>
1715        <entry><literal><function>quote_literal(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1716        <entry><type>text</type></entry>
1717        <entry>
1718         Coerce the given value to text and then quote it as a literal.
1719         Embedded single-quotes and backslashes are properly doubled.
1720        </entry>
1721        <entry><literal>quote_literal(42.5)</literal></entry>
1722        <entry><literal>'42.5'</literal></entry>
1723       </row>
1724
1725       <row>
1726        <entry>
1727         <indexterm>
1728          <primary>quote_nullable</primary>
1729         </indexterm>
1730         <literal><function>quote_nullable(<parameter>string</parameter> <type>text</type>)</function></literal>
1731        </entry>
1732        <entry><type>text</type></entry>
1733        <entry>
1734         Return the given string suitably quoted to be used as a string literal
1735         in an <acronym>SQL</acronym> statement string; or, if the argument
1736         is null, return <literal>NULL</>.
1737         Embedded single-quotes and backslashes are properly doubled.
1738         See also <xref linkend="plpgsql-quote-literal-example">.
1739        </entry>
1740        <entry><literal>quote_nullable(NULL)</literal></entry>
1741        <entry><literal>NULL</literal></entry>
1742       </row>
1743
1744       <row>
1745        <entry><literal><function>quote_nullable(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1746        <entry><type>text</type></entry>
1747        <entry>
1748         Coerce the given value to text and then quote it as a literal;
1749         or, if the argument is null, return <literal>NULL</>.
1750         Embedded single-quotes and backslashes are properly doubled.
1751        </entry>
1752        <entry><literal>quote_nullable(42.5)</literal></entry>
1753        <entry><literal>'42.5'</literal></entry>
1754       </row>
1755
1756       <row>
1757        <entry>
1758         <indexterm>
1759          <primary>regexp_matches</primary>
1760         </indexterm>
1761         <literal><function>regexp_matches(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
1762        </entry>
1763        <entry><type>setof text[]</type></entry>
1764        <entry>
1765         Return all captured substrings resulting from matching a POSIX regular
1766         expression against the <parameter>string</parameter>. See
1767         <xref linkend="functions-posix-regexp"> for more information.
1768        </entry>
1769        <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
1770        <entry><literal>{bar,beque}</literal></entry>
1771       </row>
1772
1773       <row>
1774        <entry>
1775         <indexterm>
1776          <primary>regexp_replace</primary>
1777         </indexterm>
1778         <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>
1779        </entry>
1780        <entry><type>text</type></entry>
1781        <entry>
1782         Replace substring(s) matching a POSIX regular expression. See
1783         <xref linkend="functions-posix-regexp"> for more information.
1784        </entry>
1785        <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
1786        <entry><literal>ThM</literal></entry>
1787       </row>
1788
1789       <row>
1790        <entry>
1791         <indexterm>
1792          <primary>regexp_split_to_array</primary>
1793         </indexterm>
1794         <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>
1795        </entry>
1796        <entry><type>text[]</type></entry>
1797        <entry>
1798         Split <parameter>string</parameter> using a POSIX regular expression as
1799         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1800         information.
1801        </entry>
1802        <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
1803        <entry><literal>{hello,world}</literal></entry>
1804       </row>
1805
1806       <row>
1807        <entry>
1808         <indexterm>
1809          <primary>regexp_split_to_table</primary>
1810         </indexterm>
1811         <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>
1812        </entry>
1813        <entry><type>setof text</type></entry>
1814        <entry>
1815         Split <parameter>string</parameter> using a POSIX regular expression as
1816         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1817         information.
1818        </entry>
1819        <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
1820        <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
1821       </row>
1822
1823       <row>
1824        <entry>
1825         <indexterm>
1826          <primary>repeat</primary>
1827         </indexterm>
1828         <literal><function>repeat(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</function></literal>
1829        </entry>
1830        <entry><type>text</type></entry>
1831        <entry>Repeat <parameter>string</parameter> the specified
1832        <parameter>number</parameter> of times</entry>
1833        <entry><literal>repeat('Pg', 4)</literal></entry>
1834        <entry><literal>PgPgPgPg</literal></entry>
1835       </row>
1836
1837       <row>
1838        <entry>
1839         <indexterm>
1840          <primary>replace</primary>
1841         </indexterm>
1842         <literal><function>replace(<parameter>string</parameter> <type>text</type>,
1843         <parameter>from</parameter> <type>text</type>,
1844         <parameter>to</parameter> <type>text</type>)</function></literal>
1845        </entry>
1846        <entry><type>text</type></entry>
1847        <entry>Replace all occurrences in <parameter>string</parameter> of substring
1848         <parameter>from</parameter> with substring <parameter>to</parameter>
1849        </entry>
1850        <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
1851        <entry><literal>abXXefabXXef</literal></entry>
1852       </row>
1853
1854       <row>
1855        <entry>
1856         <indexterm>
1857          <primary>reverse</primary>
1858         </indexterm>
1859         <literal><function>reverse(<parameter>str</parameter>)</function></literal>
1860        </entry>
1861        <entry><type>text</type></entry>
1862        <entry>
1863         Return reversed string.
1864        </entry>
1865        <entry><literal>reverse('abcde')</literal></entry>
1866        <entry><literal>edcba</literal></entry>
1867       </row>
1868
1869       <row>
1870        <entry>
1871         <indexterm>
1872          <primary>right</primary>
1873         </indexterm>
1874         <literal><function>right(<parameter>str</parameter> <type>text</type>,
1875          <parameter>n</parameter> <type>int</type>)</function></literal>
1876        </entry>
1877        <entry><type>text</type></entry>
1878        <entry>
1879         Return last <replaceable>n</> characters in the string. When <replaceable>n</>
1880         is negative, return all but first |<replaceable>n</>| characters.
1881        </entry>
1882        <entry><literal>right('abcde', 2)</literal></entry>
1883        <entry><literal>de</literal></entry>
1884       </row>
1885
1886       <row>
1887        <entry>
1888         <indexterm>
1889          <primary>rpad</primary>
1890         </indexterm>
1891         <literal><function>rpad(<parameter>string</parameter> <type>text</type>,
1892         <parameter>length</parameter> <type>int</type>
1893         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1894        </entry>
1895        <entry><type>text</type></entry>
1896        <entry>
1897         Fill up the <parameter>string</parameter> to length
1898         <parameter>length</parameter> by appending the characters
1899         <parameter>fill</parameter> (a space by default).  If the
1900         <parameter>string</parameter> is already longer than
1901         <parameter>length</parameter> then it is truncated.
1902        </entry>
1903        <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
1904        <entry><literal>hixyx</literal></entry>
1905       </row>
1906
1907       <row>
1908        <entry>
1909         <indexterm>
1910          <primary>rtrim</primary>
1911         </indexterm>
1912         <literal><function>rtrim(<parameter>string</parameter> <type>text</type>
1913          <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1914        </entry>
1915        <entry><type>text</type></entry>
1916        <entry>
1917         Remove the longest string containing only characters from
1918         <parameter>characters</parameter> (a space by default) from the end of
1919         <parameter>string</parameter>
1920        </entry>
1921        <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
1922        <entry><literal>trim</literal></entry>
1923       </row>
1924
1925       <row>
1926        <entry>
1927         <indexterm>
1928          <primary>split_part</primary>
1929         </indexterm>
1930         <literal><function>split_part(<parameter>string</parameter> <type>text</type>,
1931         <parameter>delimiter</parameter> <type>text</type>,
1932         <parameter>field</parameter> <type>int</type>)</function></literal>
1933        </entry>
1934        <entry><type>text</type></entry>
1935        <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1936         and return the given field (counting from one)
1937        </entry>
1938        <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
1939        <entry><literal>def</literal></entry>
1940       </row>
1941
1942       <row>
1943        <entry>
1944         <indexterm>
1945          <primary>strpos</primary>
1946         </indexterm>
1947         <literal><function>strpos(<parameter>string</parameter>, <parameter>substring</parameter>)</function></literal>
1948        </entry>
1949        <entry><type>int</type></entry>
1950        <entry>
1951         Location of specified substring (same as
1952         <literal>position(<parameter>substring</parameter> in
1953          <parameter>string</parameter>)</literal>, but note the reversed
1954         argument order)
1955        </entry>
1956        <entry><literal>strpos('high', 'ig')</literal></entry>
1957        <entry><literal>2</literal></entry>
1958       </row>
1959
1960       <row>
1961        <entry>
1962         <indexterm>
1963          <primary>substr</primary>
1964         </indexterm>
1965         <literal><function>substr(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</function></literal>
1966        </entry>
1967        <entry><type>text</type></entry>
1968        <entry>
1969         Extract substring (same as
1970         <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
1971        </entry>
1972        <entry><literal>substr('alphabet', 3, 2)</literal></entry>
1973        <entry><literal>ph</literal></entry>
1974       </row>
1975
1976       <row>
1977        <entry>
1978         <indexterm>
1979          <primary>to_ascii</primary>
1980         </indexterm>
1981         <literal><function>to_ascii(<parameter>string</parameter> <type>text</type>
1982         <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</function></literal>
1983        </entry>
1984        <entry><type>text</type></entry>
1985        <entry>
1986        Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
1987        (only supports conversion from  <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
1988        and <literal>WIN1250</> encodings)
1989        </entry>
1990        <entry><literal>to_ascii('Karel')</literal></entry>
1991        <entry><literal>Karel</literal></entry>
1992       </row>
1993
1994       <row>
1995        <entry>
1996         <indexterm>
1997          <primary>to_hex</primary>
1998         </indexterm>
1999         <literal><function>to_hex(<parameter>number</parameter> <type>int</type>
2000         or <type>bigint</type>)</function></literal>
2001        </entry>
2002        <entry><type>text</type></entry>
2003        <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
2004         representation
2005        </entry>
2006        <entry><literal>to_hex(2147483647)</literal></entry>
2007        <entry><literal>7fffffff</literal></entry>
2008       </row>
2009
2010       <row>
2011        <entry>
2012         <indexterm>
2013          <primary>translate</primary>
2014         </indexterm>
2015         <literal><function>translate(<parameter>string</parameter> <type>text</type>,
2016         <parameter>from</parameter> <type>text</type>,
2017         <parameter>to</parameter> <type>text</type>)</function></literal>
2018        </entry>
2019        <entry><type>text</type></entry>
2020        <entry>
2021         Any character in <parameter>string</parameter> that matches a
2022         character in the <parameter>from</parameter> set is replaced by
2023         the corresponding character in the <parameter>to</parameter>
2024         set. If <parameter>from</parameter> is longer than
2025         <parameter>to</parameter>, occurrences of the extra characters in
2026         <parameter>from</parameter> are removed.
2027        </entry>
2028        <entry><literal>translate('12345', '143', 'ax')</literal></entry>
2029        <entry><literal>a2x5</literal></entry>
2030       </row>
2031
2032      </tbody>
2033     </tgroup>
2034    </table>
2035
2036    <para>
2037    See also the aggregate function <function>string_agg</function> in
2038    <xref linkend="functions-aggregate">.
2039    </para>
2040
2041    <table id="conversion-names">
2042     <title>Built-in Conversions</title>
2043     <tgroup cols="3">
2044      <thead>
2045       <row>
2046        <entry>Conversion Name
2047         <footnote>
2048          <para>
2049           The conversion names follow a standard naming scheme: The
2050           official name of the source encoding with all
2051           non-alphanumeric characters replaced by underscores, followed
2052           by <literal>_to_</literal>, followed by the similarly processed
2053           destination encoding name. Therefore, the names might deviate
2054           from the customary encoding names.
2055          </para>
2056         </footnote>
2057        </entry>
2058        <entry>Source Encoding</entry>
2059        <entry>Destination Encoding</entry>
2060       </row>
2061      </thead>
2062
2063      <tbody>
2064       <row>
2065        <entry><literal>ascii_to_mic</literal></entry>
2066        <entry><literal>SQL_ASCII</literal></entry>
2067        <entry><literal>MULE_INTERNAL</literal></entry>
2068       </row>
2069
2070       <row>
2071        <entry><literal>ascii_to_utf8</literal></entry>
2072        <entry><literal>SQL_ASCII</literal></entry>
2073        <entry><literal>UTF8</literal></entry>
2074       </row>
2075
2076       <row>
2077        <entry><literal>big5_to_euc_tw</literal></entry>
2078        <entry><literal>BIG5</literal></entry>
2079        <entry><literal>EUC_TW</literal></entry>
2080       </row>
2081
2082       <row>
2083        <entry><literal>big5_to_mic</literal></entry>
2084        <entry><literal>BIG5</literal></entry>
2085        <entry><literal>MULE_INTERNAL</literal></entry>
2086       </row>
2087
2088       <row>
2089        <entry><literal>big5_to_utf8</literal></entry>
2090        <entry><literal>BIG5</literal></entry>
2091        <entry><literal>UTF8</literal></entry>
2092       </row>
2093
2094       <row>
2095        <entry><literal>euc_cn_to_mic</literal></entry>
2096        <entry><literal>EUC_CN</literal></entry>
2097        <entry><literal>MULE_INTERNAL</literal></entry>
2098       </row>
2099
2100       <row>
2101        <entry><literal>euc_cn_to_utf8</literal></entry>
2102        <entry><literal>EUC_CN</literal></entry>
2103        <entry><literal>UTF8</literal></entry>
2104       </row>
2105
2106       <row>
2107        <entry><literal>euc_jp_to_mic</literal></entry>
2108        <entry><literal>EUC_JP</literal></entry>
2109        <entry><literal>MULE_INTERNAL</literal></entry>
2110       </row>
2111
2112       <row>
2113        <entry><literal>euc_jp_to_sjis</literal></entry>
2114        <entry><literal>EUC_JP</literal></entry>
2115        <entry><literal>SJIS</literal></entry>
2116       </row>
2117
2118       <row>
2119        <entry><literal>euc_jp_to_utf8</literal></entry>
2120        <entry><literal>EUC_JP</literal></entry>
2121        <entry><literal>UTF8</literal></entry>
2122       </row>
2123
2124       <row>
2125        <entry><literal>euc_kr_to_mic</literal></entry>
2126        <entry><literal>EUC_KR</literal></entry>
2127        <entry><literal>MULE_INTERNAL</literal></entry>
2128       </row>
2129
2130       <row>
2131        <entry><literal>euc_kr_to_utf8</literal></entry>
2132        <entry><literal>EUC_KR</literal></entry>
2133        <entry><literal>UTF8</literal></entry>
2134       </row>
2135
2136       <row>
2137        <entry><literal>euc_tw_to_big5</literal></entry>
2138        <entry><literal>EUC_TW</literal></entry>
2139        <entry><literal>BIG5</literal></entry>
2140       </row>
2141
2142       <row>
2143        <entry><literal>euc_tw_to_mic</literal></entry>
2144        <entry><literal>EUC_TW</literal></entry>
2145        <entry><literal>MULE_INTERNAL</literal></entry>
2146       </row>
2147
2148       <row>
2149        <entry><literal>euc_tw_to_utf8</literal></entry>
2150        <entry><literal>EUC_TW</literal></entry>
2151        <entry><literal>UTF8</literal></entry>
2152       </row>
2153
2154       <row>
2155        <entry><literal>gb18030_to_utf8</literal></entry>
2156        <entry><literal>GB18030</literal></entry>
2157        <entry><literal>UTF8</literal></entry>
2158       </row>
2159
2160       <row>
2161        <entry><literal>gbk_to_utf8</literal></entry>
2162        <entry><literal>GBK</literal></entry>
2163        <entry><literal>UTF8</literal></entry>
2164       </row>
2165
2166       <row>
2167        <entry><literal>iso_8859_10_to_utf8</literal></entry>
2168        <entry><literal>LATIN6</literal></entry>
2169        <entry><literal>UTF8</literal></entry>
2170       </row>
2171
2172       <row>
2173        <entry><literal>iso_8859_13_to_utf8</literal></entry>
2174        <entry><literal>LATIN7</literal></entry>
2175        <entry><literal>UTF8</literal></entry>
2176       </row>
2177
2178       <row>
2179        <entry><literal>iso_8859_14_to_utf8</literal></entry>
2180        <entry><literal>LATIN8</literal></entry>
2181        <entry><literal>UTF8</literal></entry>
2182       </row>
2183
2184       <row>
2185        <entry><literal>iso_8859_15_to_utf8</literal></entry>
2186        <entry><literal>LATIN9</literal></entry>
2187        <entry><literal>UTF8</literal></entry>
2188       </row>
2189
2190       <row>
2191        <entry><literal>iso_8859_16_to_utf8</literal></entry>
2192        <entry><literal>LATIN10</literal></entry>
2193        <entry><literal>UTF8</literal></entry>
2194       </row>
2195
2196       <row>
2197        <entry><literal>iso_8859_1_to_mic</literal></entry>
2198        <entry><literal>LATIN1</literal></entry>
2199        <entry><literal>MULE_INTERNAL</literal></entry>
2200       </row>
2201
2202       <row>
2203        <entry><literal>iso_8859_1_to_utf8</literal></entry>
2204        <entry><literal>LATIN1</literal></entry>
2205        <entry><literal>UTF8</literal></entry>
2206       </row>
2207
2208       <row>
2209        <entry><literal>iso_8859_2_to_mic</literal></entry>
2210        <entry><literal>LATIN2</literal></entry>
2211        <entry><literal>MULE_INTERNAL</literal></entry>
2212       </row>
2213
2214       <row>
2215        <entry><literal>iso_8859_2_to_utf8</literal></entry>
2216        <entry><literal>LATIN2</literal></entry>
2217        <entry><literal>UTF8</literal></entry>
2218       </row>
2219
2220       <row>
2221        <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
2222        <entry><literal>LATIN2</literal></entry>
2223        <entry><literal>WIN1250</literal></entry>
2224       </row>
2225
2226       <row>
2227        <entry><literal>iso_8859_3_to_mic</literal></entry>
2228        <entry><literal>LATIN3</literal></entry>
2229        <entry><literal>MULE_INTERNAL</literal></entry>
2230       </row>
2231
2232       <row>
2233        <entry><literal>iso_8859_3_to_utf8</literal></entry>
2234        <entry><literal>LATIN3</literal></entry>
2235        <entry><literal>UTF8</literal></entry>
2236       </row>
2237
2238       <row>
2239        <entry><literal>iso_8859_4_to_mic</literal></entry>
2240        <entry><literal>LATIN4</literal></entry>
2241        <entry><literal>MULE_INTERNAL</literal></entry>
2242       </row>
2243
2244       <row>
2245        <entry><literal>iso_8859_4_to_utf8</literal></entry>
2246        <entry><literal>LATIN4</literal></entry>
2247        <entry><literal>UTF8</literal></entry>
2248       </row>
2249
2250       <row>
2251        <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
2252        <entry><literal>ISO_8859_5</literal></entry>
2253        <entry><literal>KOI8R</literal></entry>
2254       </row>
2255
2256       <row>
2257        <entry><literal>iso_8859_5_to_mic</literal></entry>
2258        <entry><literal>ISO_8859_5</literal></entry>
2259        <entry><literal>MULE_INTERNAL</literal></entry>
2260       </row>
2261
2262       <row>
2263        <entry><literal>iso_8859_5_to_utf8</literal></entry>
2264        <entry><literal>ISO_8859_5</literal></entry>
2265        <entry><literal>UTF8</literal></entry>
2266       </row>
2267
2268       <row>
2269        <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
2270        <entry><literal>ISO_8859_5</literal></entry>
2271        <entry><literal>WIN1251</literal></entry>
2272       </row>
2273
2274       <row>
2275        <entry><literal>iso_8859_5_to_windows_866</literal></entry>
2276        <entry><literal>ISO_8859_5</literal></entry>
2277        <entry><literal>WIN866</literal></entry>
2278       </row>
2279
2280       <row>
2281        <entry><literal>iso_8859_6_to_utf8</literal></entry>
2282        <entry><literal>ISO_8859_6</literal></entry>
2283        <entry><literal>UTF8</literal></entry>
2284       </row>
2285
2286       <row>
2287        <entry><literal>iso_8859_7_to_utf8</literal></entry>
2288        <entry><literal>ISO_8859_7</literal></entry>
2289        <entry><literal>UTF8</literal></entry>
2290       </row>
2291
2292       <row>
2293        <entry><literal>iso_8859_8_to_utf8</literal></entry>
2294        <entry><literal>ISO_8859_8</literal></entry>
2295        <entry><literal>UTF8</literal></entry>
2296       </row>
2297
2298       <row>
2299        <entry><literal>iso_8859_9_to_utf8</literal></entry>
2300        <entry><literal>LATIN5</literal></entry>
2301        <entry><literal>UTF8</literal></entry>
2302       </row>
2303
2304       <row>
2305        <entry><literal>johab_to_utf8</literal></entry>
2306        <entry><literal>JOHAB</literal></entry>
2307        <entry><literal>UTF8</literal></entry>
2308       </row>
2309
2310       <row>
2311        <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
2312        <entry><literal>KOI8R</literal></entry>
2313        <entry><literal>ISO_8859_5</literal></entry>
2314       </row>
2315
2316       <row>
2317        <entry><literal>koi8_r_to_mic</literal></entry>
2318        <entry><literal>KOI8R</literal></entry>
2319        <entry><literal>MULE_INTERNAL</literal></entry>
2320       </row>
2321
2322       <row>
2323        <entry><literal>koi8_r_to_utf8</literal></entry>
2324        <entry><literal>KOI8R</literal></entry>
2325        <entry><literal>UTF8</literal></entry>
2326       </row>
2327
2328       <row>
2329        <entry><literal>koi8_r_to_windows_1251</literal></entry>
2330        <entry><literal>KOI8R</literal></entry>
2331        <entry><literal>WIN1251</literal></entry>
2332       </row>
2333
2334       <row>
2335        <entry><literal>koi8_r_to_windows_866</literal></entry>
2336        <entry><literal>KOI8R</literal></entry>
2337        <entry><literal>WIN866</literal></entry>
2338       </row>
2339
2340       <row>
2341        <entry><literal>koi8_u_to_utf8</literal></entry>
2342        <entry><literal>KOI8U</literal></entry>
2343        <entry><literal>UTF8</literal></entry>
2344       </row>
2345
2346       <row>
2347        <entry><literal>mic_to_ascii</literal></entry>
2348        <entry><literal>MULE_INTERNAL</literal></entry>
2349        <entry><literal>SQL_ASCII</literal></entry>
2350       </row>
2351
2352       <row>
2353        <entry><literal>mic_to_big5</literal></entry>
2354        <entry><literal>MULE_INTERNAL</literal></entry>
2355        <entry><literal>BIG5</literal></entry>
2356       </row>
2357
2358       <row>
2359        <entry><literal>mic_to_euc_cn</literal></entry>
2360        <entry><literal>MULE_INTERNAL</literal></entry>
2361        <entry><literal>EUC_CN</literal></entry>
2362       </row>
2363
2364       <row>
2365        <entry><literal>mic_to_euc_jp</literal></entry>
2366        <entry><literal>MULE_INTERNAL</literal></entry>
2367        <entry><literal>EUC_JP</literal></entry>
2368       </row>
2369
2370       <row>
2371        <entry><literal>mic_to_euc_kr</literal></entry>
2372        <entry><literal>MULE_INTERNAL</literal></entry>
2373        <entry><literal>EUC_KR</literal></entry>
2374       </row>
2375
2376       <row>
2377        <entry><literal>mic_to_euc_tw</literal></entry>
2378        <entry><literal>MULE_INTERNAL</literal></entry>
2379        <entry><literal>EUC_TW</literal></entry>
2380       </row>
2381
2382       <row>
2383        <entry><literal>mic_to_iso_8859_1</literal></entry>
2384        <entry><literal>MULE_INTERNAL</literal></entry>
2385        <entry><literal>LATIN1</literal></entry>
2386       </row>
2387
2388       <row>
2389        <entry><literal>mic_to_iso_8859_2</literal></entry>
2390        <entry><literal>MULE_INTERNAL</literal></entry>
2391        <entry><literal>LATIN2</literal></entry>
2392       </row>
2393
2394       <row>
2395        <entry><literal>mic_to_iso_8859_3</literal></entry>
2396        <entry><literal>MULE_INTERNAL</literal></entry>
2397        <entry><literal>LATIN3</literal></entry>
2398       </row>
2399
2400       <row>
2401        <entry><literal>mic_to_iso_8859_4</literal></entry>
2402        <entry><literal>MULE_INTERNAL</literal></entry>
2403        <entry><literal>LATIN4</literal></entry>
2404       </row>
2405
2406       <row>
2407        <entry><literal>mic_to_iso_8859_5</literal></entry>
2408        <entry><literal>MULE_INTERNAL</literal></entry>
2409        <entry><literal>ISO_8859_5</literal></entry>
2410       </row>
2411
2412       <row>
2413        <entry><literal>mic_to_koi8_r</literal></entry>
2414        <entry><literal>MULE_INTERNAL</literal></entry>
2415        <entry><literal>KOI8R</literal></entry>
2416       </row>
2417
2418       <row>
2419        <entry><literal>mic_to_sjis</literal></entry>
2420        <entry><literal>MULE_INTERNAL</literal></entry>
2421        <entry><literal>SJIS</literal></entry>
2422       </row>
2423
2424       <row>
2425        <entry><literal>mic_to_windows_1250</literal></entry>
2426        <entry><literal>MULE_INTERNAL</literal></entry>
2427        <entry><literal>WIN1250</literal></entry>
2428       </row>
2429
2430       <row>
2431        <entry><literal>mic_to_windows_1251</literal></entry>
2432        <entry><literal>MULE_INTERNAL</literal></entry>
2433        <entry><literal>WIN1251</literal></entry>
2434       </row>
2435
2436       <row>
2437        <entry><literal>mic_to_windows_866</literal></entry>
2438        <entry><literal>MULE_INTERNAL</literal></entry>
2439        <entry><literal>WIN866</literal></entry>
2440       </row>
2441
2442       <row>
2443        <entry><literal>sjis_to_euc_jp</literal></entry>
2444        <entry><literal>SJIS</literal></entry>
2445        <entry><literal>EUC_JP</literal></entry>
2446       </row>
2447
2448       <row>
2449        <entry><literal>sjis_to_mic</literal></entry>
2450        <entry><literal>SJIS</literal></entry>
2451        <entry><literal>MULE_INTERNAL</literal></entry>
2452       </row>
2453
2454       <row>
2455        <entry><literal>sjis_to_utf8</literal></entry>
2456        <entry><literal>SJIS</literal></entry>
2457        <entry><literal>UTF8</literal></entry>
2458       </row>
2459
2460       <row>
2461        <entry><literal>tcvn_to_utf8</literal></entry>
2462        <entry><literal>WIN1258</literal></entry>
2463        <entry><literal>UTF8</literal></entry>
2464       </row>
2465
2466       <row>
2467        <entry><literal>uhc_to_utf8</literal></entry>
2468        <entry><literal>UHC</literal></entry>
2469        <entry><literal>UTF8</literal></entry>
2470       </row>
2471
2472       <row>
2473        <entry><literal>utf8_to_ascii</literal></entry>
2474        <entry><literal>UTF8</literal></entry>
2475        <entry><literal>SQL_ASCII</literal></entry>
2476       </row>
2477
2478       <row>
2479        <entry><literal>utf8_to_big5</literal></entry>
2480        <entry><literal>UTF8</literal></entry>
2481        <entry><literal>BIG5</literal></entry>
2482       </row>
2483
2484       <row>
2485        <entry><literal>utf8_to_euc_cn</literal></entry>
2486        <entry><literal>UTF8</literal></entry>
2487        <entry><literal>EUC_CN</literal></entry>
2488       </row>
2489
2490       <row>
2491        <entry><literal>utf8_to_euc_jp</literal></entry>
2492        <entry><literal>UTF8</literal></entry>
2493        <entry><literal>EUC_JP</literal></entry>
2494       </row>
2495
2496       <row>
2497        <entry><literal>utf8_to_euc_kr</literal></entry>
2498        <entry><literal>UTF8</literal></entry>
2499        <entry><literal>EUC_KR</literal></entry>
2500       </row>
2501
2502       <row>
2503        <entry><literal>utf8_to_euc_tw</literal></entry>
2504        <entry><literal>UTF8</literal></entry>
2505        <entry><literal>EUC_TW</literal></entry>
2506       </row>
2507
2508       <row>
2509        <entry><literal>utf8_to_gb18030</literal></entry>
2510        <entry><literal>UTF8</literal></entry>
2511        <entry><literal>GB18030</literal></entry>
2512       </row>
2513
2514       <row>
2515        <entry><literal>utf8_to_gbk</literal></entry>
2516        <entry><literal>UTF8</literal></entry>
2517        <entry><literal>GBK</literal></entry>
2518       </row>
2519
2520       <row>
2521        <entry><literal>utf8_to_iso_8859_1</literal></entry>
2522        <entry><literal>UTF8</literal></entry>
2523        <entry><literal>LATIN1</literal></entry>
2524       </row>
2525
2526       <row>
2527        <entry><literal>utf8_to_iso_8859_10</literal></entry>
2528        <entry><literal>UTF8</literal></entry>
2529        <entry><literal>LATIN6</literal></entry>
2530       </row>
2531
2532       <row>
2533        <entry><literal>utf8_to_iso_8859_13</literal></entry>
2534        <entry><literal>UTF8</literal></entry>
2535        <entry><literal>LATIN7</literal></entry>
2536       </row>
2537
2538       <row>
2539        <entry><literal>utf8_to_iso_8859_14</literal></entry>
2540        <entry><literal>UTF8</literal></entry>
2541        <entry><literal>LATIN8</literal></entry>
2542       </row>
2543
2544       <row>
2545        <entry><literal>utf8_to_iso_8859_15</literal></entry>
2546        <entry><literal>UTF8</literal></entry>
2547        <entry><literal>LATIN9</literal></entry>
2548       </row>
2549
2550       <row>
2551        <entry><literal>utf8_to_iso_8859_16</literal></entry>
2552        <entry><literal>UTF8</literal></entry>
2553        <entry><literal>LATIN10</literal></entry>
2554       </row>
2555
2556       <row>
2557        <entry><literal>utf8_to_iso_8859_2</literal></entry>
2558        <entry><literal>UTF8</literal></entry>
2559        <entry><literal>LATIN2</literal></entry>
2560       </row>
2561
2562       <row>
2563        <entry><literal>utf8_to_iso_8859_3</literal></entry>
2564        <entry><literal>UTF8</literal></entry>
2565        <entry><literal>LATIN3</literal></entry>
2566       </row>
2567
2568       <row>
2569        <entry><literal>utf8_to_iso_8859_4</literal></entry>
2570        <entry><literal>UTF8</literal></entry>
2571        <entry><literal>LATIN4</literal></entry>
2572       </row>
2573
2574       <row>
2575        <entry><literal>utf8_to_iso_8859_5</literal></entry>
2576        <entry><literal>UTF8</literal></entry>
2577        <entry><literal>ISO_8859_5</literal></entry>
2578       </row>
2579
2580       <row>
2581        <entry><literal>utf8_to_iso_8859_6</literal></entry>
2582        <entry><literal>UTF8</literal></entry>
2583        <entry><literal>ISO_8859_6</literal></entry>
2584       </row>
2585
2586       <row>
2587        <entry><literal>utf8_to_iso_8859_7</literal></entry>
2588        <entry><literal>UTF8</literal></entry>
2589        <entry><literal>ISO_8859_7</literal></entry>
2590       </row>
2591
2592       <row>
2593        <entry><literal>utf8_to_iso_8859_8</literal></entry>
2594        <entry><literal>UTF8</literal></entry>
2595        <entry><literal>ISO_8859_8</literal></entry>
2596       </row>
2597
2598       <row>
2599        <entry><literal>utf8_to_iso_8859_9</literal></entry>
2600        <entry><literal>UTF8</literal></entry>
2601        <entry><literal>LATIN5</literal></entry>
2602       </row>
2603
2604       <row>
2605        <entry><literal>utf8_to_johab</literal></entry>
2606        <entry><literal>UTF8</literal></entry>
2607        <entry><literal>JOHAB</literal></entry>
2608       </row>
2609
2610       <row>
2611        <entry><literal>utf8_to_koi8_r</literal></entry>
2612        <entry><literal>UTF8</literal></entry>
2613        <entry><literal>KOI8R</literal></entry>
2614       </row>
2615
2616       <row>
2617        <entry><literal>utf8_to_koi8_u</literal></entry>
2618        <entry><literal>UTF8</literal></entry>
2619        <entry><literal>KOI8U</literal></entry>
2620       </row>
2621
2622       <row>
2623        <entry><literal>utf8_to_sjis</literal></entry>
2624        <entry><literal>UTF8</literal></entry>
2625        <entry><literal>SJIS</literal></entry>
2626       </row>
2627
2628       <row>
2629        <entry><literal>utf8_to_tcvn</literal></entry>
2630        <entry><literal>UTF8</literal></entry>
2631        <entry><literal>WIN1258</literal></entry>
2632       </row>
2633
2634       <row>
2635        <entry><literal>utf8_to_uhc</literal></entry>
2636        <entry><literal>UTF8</literal></entry>
2637        <entry><literal>UHC</literal></entry>
2638       </row>
2639
2640       <row>
2641        <entry><literal>utf8_to_windows_1250</literal></entry>
2642        <entry><literal>UTF8</literal></entry>
2643        <entry><literal>WIN1250</literal></entry>
2644       </row>
2645
2646       <row>
2647        <entry><literal>utf8_to_windows_1251</literal></entry>
2648        <entry><literal>UTF8</literal></entry>
2649        <entry><literal>WIN1251</literal></entry>
2650       </row>
2651
2652       <row>
2653        <entry><literal>utf8_to_windows_1252</literal></entry>
2654        <entry><literal>UTF8</literal></entry>
2655        <entry><literal>WIN1252</literal></entry>
2656       </row>
2657
2658       <row>
2659        <entry><literal>utf8_to_windows_1253</literal></entry>
2660        <entry><literal>UTF8</literal></entry>
2661        <entry><literal>WIN1253</literal></entry>
2662       </row>
2663
2664       <row>
2665        <entry><literal>utf8_to_windows_1254</literal></entry>
2666        <entry><literal>UTF8</literal></entry>
2667        <entry><literal>WIN1254</literal></entry>
2668       </row>
2669
2670       <row>
2671        <entry><literal>utf8_to_windows_1255</literal></entry>
2672        <entry><literal>UTF8</literal></entry>
2673        <entry><literal>WIN1255</literal></entry>
2674       </row>
2675
2676       <row>
2677        <entry><literal>utf8_to_windows_1256</literal></entry>
2678        <entry><literal>UTF8</literal></entry>
2679        <entry><literal>WIN1256</literal></entry>
2680       </row>
2681
2682       <row>
2683        <entry><literal>utf8_to_windows_1257</literal></entry>
2684        <entry><literal>UTF8</literal></entry>
2685        <entry><literal>WIN1257</literal></entry>
2686       </row>
2687
2688       <row>
2689        <entry><literal>utf8_to_windows_866</literal></entry>
2690        <entry><literal>UTF8</literal></entry>
2691        <entry><literal>WIN866</literal></entry>
2692       </row>
2693
2694       <row>
2695        <entry><literal>utf8_to_windows_874</literal></entry>
2696        <entry><literal>UTF8</literal></entry>
2697        <entry><literal>WIN874</literal></entry>
2698       </row>
2699
2700       <row>
2701        <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
2702        <entry><literal>WIN1250</literal></entry>
2703        <entry><literal>LATIN2</literal></entry>
2704       </row>
2705
2706       <row>
2707        <entry><literal>windows_1250_to_mic</literal></entry>
2708        <entry><literal>WIN1250</literal></entry>
2709        <entry><literal>MULE_INTERNAL</literal></entry>
2710       </row>
2711
2712       <row>
2713        <entry><literal>windows_1250_to_utf8</literal></entry>
2714        <entry><literal>WIN1250</literal></entry>
2715        <entry><literal>UTF8</literal></entry>
2716       </row>
2717
2718       <row>
2719        <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
2720        <entry><literal>WIN1251</literal></entry>
2721        <entry><literal>ISO_8859_5</literal></entry>
2722       </row>
2723
2724       <row>
2725        <entry><literal>windows_1251_to_koi8_r</literal></entry>
2726        <entry><literal>WIN1251</literal></entry>
2727        <entry><literal>KOI8R</literal></entry>
2728       </row>
2729
2730       <row>
2731        <entry><literal>windows_1251_to_mic</literal></entry>
2732        <entry><literal>WIN1251</literal></entry>
2733        <entry><literal>MULE_INTERNAL</literal></entry>
2734       </row>
2735
2736       <row>
2737        <entry><literal>windows_1251_to_utf8</literal></entry>
2738        <entry><literal>WIN1251</literal></entry>
2739        <entry><literal>UTF8</literal></entry>
2740       </row>
2741
2742       <row>
2743        <entry><literal>windows_1251_to_windows_866</literal></entry>
2744        <entry><literal>WIN1251</literal></entry>
2745        <entry><literal>WIN866</literal></entry>
2746       </row>
2747
2748       <row>
2749        <entry><literal>windows_1252_to_utf8</literal></entry>
2750        <entry><literal>WIN1252</literal></entry>
2751        <entry><literal>UTF8</literal></entry>
2752       </row>
2753
2754       <row>
2755        <entry><literal>windows_1256_to_utf8</literal></entry>
2756        <entry><literal>WIN1256</literal></entry>
2757        <entry><literal>UTF8</literal></entry>
2758       </row>
2759
2760       <row>
2761        <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2762        <entry><literal>WIN866</literal></entry>
2763        <entry><literal>ISO_8859_5</literal></entry>
2764       </row>
2765
2766       <row>
2767        <entry><literal>windows_866_to_koi8_r</literal></entry>
2768        <entry><literal>WIN866</literal></entry>
2769        <entry><literal>KOI8R</literal></entry>
2770       </row>
2771
2772       <row>
2773        <entry><literal>windows_866_to_mic</literal></entry>
2774        <entry><literal>WIN866</literal></entry>
2775        <entry><literal>MULE_INTERNAL</literal></entry>
2776       </row>
2777
2778       <row>
2779        <entry><literal>windows_866_to_utf8</literal></entry>
2780        <entry><literal>WIN866</literal></entry>
2781        <entry><literal>UTF8</literal></entry>
2782       </row>
2783
2784       <row>
2785        <entry><literal>windows_866_to_windows_1251</literal></entry>
2786        <entry><literal>WIN866</literal></entry>
2787        <entry><literal>WIN</literal></entry>
2788       </row>
2789
2790       <row>
2791        <entry><literal>windows_874_to_utf8</literal></entry>
2792        <entry><literal>WIN874</literal></entry>
2793        <entry><literal>UTF8</literal></entry>
2794       </row>
2795
2796       <row>
2797        <entry><literal>euc_jis_2004_to_utf8</literal></entry>
2798        <entry><literal>EUC_JIS_2004</literal></entry>
2799        <entry><literal>UTF8</literal></entry>
2800       </row>
2801
2802       <row>
2803        <entry><literal>ut8_to_euc_jis_2004</literal></entry>
2804        <entry><literal>UTF8</literal></entry>
2805        <entry><literal>EUC_JIS_2004</literal></entry>
2806       </row>
2807
2808       <row>
2809        <entry><literal>shift_jis_2004_to_utf8</literal></entry>
2810        <entry><literal>SHIFT_JIS_2004</literal></entry>
2811        <entry><literal>UTF8</literal></entry>
2812       </row>
2813
2814       <row>
2815        <entry><literal>ut8_to_shift_jis_2004</literal></entry>
2816        <entry><literal>UTF8</literal></entry>
2817        <entry><literal>SHIFT_JIS_2004</literal></entry>
2818       </row>
2819
2820       <row>
2821        <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
2822        <entry><literal>EUC_JIS_2004</literal></entry>
2823        <entry><literal>SHIFT_JIS_2004</literal></entry>
2824       </row>
2825
2826       <row>
2827        <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
2828        <entry><literal>SHIFT_JIS_2004</literal></entry>
2829        <entry><literal>EUC_JIS_2004</literal></entry>
2830       </row>
2831
2832      </tbody>
2833     </tgroup>
2834    </table>
2835
2836   </sect1>
2837
2838
2839   <sect1 id="functions-binarystring">
2840    <title>Binary String Functions and Operators</title>
2841
2842    <indexterm zone="functions-binarystring">
2843     <primary>binary data</primary>
2844     <secondary>functions</secondary>
2845    </indexterm>
2846
2847    <para>
2848     This section describes functions and operators for examining and
2849     manipulating values of type <type>bytea</type>.
2850    </para>
2851
2852    <para>
2853     <acronym>SQL</acronym> defines some string functions that use
2854     key words, rather than commas, to separate
2855     arguments.  Details are in
2856     <xref linkend="functions-binarystring-sql">.
2857     <productname>PostgreSQL</> also provides versions of these functions
2858     that use the regular function invocation syntax
2859     (see <xref linkend="functions-binarystring-other">).
2860    </para>
2861
2862    <note>
2863     <para>
2864      The sample results shown on this page assume that the server parameter
2865      <link linkend="guc-bytea-output"><varname>bytea_output</></link> is set
2866      to <literal>escape</literal> (the traditional PostgreSQL format).
2867     </para>
2868    </note>
2869
2870    <table id="functions-binarystring-sql">
2871     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
2872     <tgroup cols="5">
2873      <thead>
2874       <row>
2875        <entry>Function</entry>
2876        <entry>Return Type</entry>
2877        <entry>Description</entry>
2878        <entry>Example</entry>
2879        <entry>Result</entry>
2880       </row>
2881      </thead>
2882
2883      <tbody>
2884       <row>
2885        <entry><literal><parameter>string</parameter> <literal>||</literal>
2886         <parameter>string</parameter></literal></entry>
2887        <entry> <type>bytea</type> </entry>
2888        <entry>
2889         String concatenation
2890         <indexterm>
2891          <primary>binary string</primary>
2892          <secondary>concatenation</secondary>
2893         </indexterm>
2894        </entry>
2895        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
2896        <entry><literal>\\Post'gres\000</literal></entry>
2897       </row>
2898
2899       <row>
2900        <entry>
2901         <indexterm>
2902          <primary>octet_length</primary>
2903         </indexterm>
2904         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
2905        </entry>
2906        <entry><type>int</type></entry>
2907        <entry>Number of bytes in binary string</entry>
2908        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
2909        <entry><literal>5</literal></entry>
2910       </row>
2911
2912       <row>
2913        <entry>
2914         <indexterm>
2915          <primary>overlay</primary>
2916         </indexterm>
2917         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
2918        </entry>
2919        <entry><type>bytea</type></entry>
2920        <entry>
2921         Replace substring
2922        </entry>
2923        <entry><literal>overlay(E'Th\\000omas'::bytea placing E'\\002\\003'::bytea from 2 for 3)</literal></entry>
2924        <entry><literal>T\\002\\003mas</literal></entry>
2925       </row>
2926
2927       <row>
2928        <entry>
2929         <indexterm>
2930          <primary>position</primary>
2931         </indexterm>
2932         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
2933        </entry>
2934        <entry><type>int</type></entry>
2935        <entry>Location of specified substring</entry>
2936       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
2937        <entry><literal>3</literal></entry>
2938       </row>
2939
2940       <row>
2941        <entry>
2942         <indexterm>
2943          <primary>substring</primary>
2944         </indexterm>
2945         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
2946        </entry>
2947        <entry><type>bytea</type></entry>
2948        <entry>
2949         Extract substring
2950        </entry>
2951        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
2952        <entry><literal>h\000o</literal></entry>
2953       </row>
2954
2955       <row>
2956        <entry>
2957         <indexterm>
2958          <primary>trim</primary>
2959         </indexterm>
2960         <literal><function>trim(<optional>both</optional>
2961         <parameter>bytes</parameter> from
2962         <parameter>string</parameter>)</function></literal>
2963        </entry>
2964        <entry><type>bytea</type></entry>
2965        <entry>
2966         Remove the longest string containing only the bytes in
2967         <parameter>bytes</parameter> from the start
2968         and end of <parameter>string</parameter>
2969        </entry>
2970        <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
2971        <entry><literal>Tom</literal></entry>
2972       </row>
2973      </tbody>
2974     </tgroup>
2975    </table>
2976
2977    <para>
2978     Additional binary string manipulation functions are available and
2979     are listed in <xref linkend="functions-binarystring-other">.  Some
2980     of them are used internally to implement the
2981     <acronym>SQL</acronym>-standard string functions listed in <xref
2982     linkend="functions-binarystring-sql">.
2983    </para>
2984
2985    <table id="functions-binarystring-other">
2986     <title>Other Binary String Functions</title>
2987     <tgroup cols="5">
2988      <thead>
2989       <row>
2990        <entry>Function</entry>
2991        <entry>Return Type</entry>
2992        <entry>Description</entry>
2993        <entry>Example</entry>
2994        <entry>Result</entry>
2995       </row>
2996      </thead>
2997
2998      <tbody>
2999       <row>
3000        <entry>
3001         <indexterm>
3002          <primary>btrim</primary>
3003         </indexterm>
3004         <literal><function>btrim(<parameter>string</parameter>
3005         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</function></literal>
3006        </entry>
3007        <entry><type>bytea</type></entry>
3008        <entry>
3009         Remove the longest string consisting only of bytes
3010         in <parameter>bytes</parameter> from the start and end of
3011         <parameter>string</parameter>
3012       </entry>
3013       <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
3014       <entry><literal>trim</literal></entry>
3015      </row>
3016
3017      <row>
3018       <entry>
3019         <indexterm>
3020          <primary>decode</primary>
3021         </indexterm>
3022        <literal><function>decode(<parameter>string</parameter> <type>text</type>,
3023               <parameter>type</parameter> <type>text</type>)</function></literal>
3024       </entry>
3025       <entry><type>bytea</type></entry>
3026       <entry>
3027        Decode binary string from <parameter>string</parameter> previously
3028        encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
3029       </entry>
3030       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
3031       <entry><literal>123\000456</literal></entry>
3032      </row>
3033
3034      <row>
3035       <entry>
3036         <indexterm>
3037          <primary>encode</primary>
3038         </indexterm>
3039        <literal><function>encode(<parameter>string</parameter> <type>bytea</type>,
3040               <parameter>type</parameter> <type>text</type>)</function></literal>
3041       </entry>
3042       <entry><type>text</type></entry>
3043       <entry>
3044        Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
3045        types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
3046       </entry>
3047       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
3048       <entry><literal>123\000456</literal></entry>
3049      </row>
3050
3051       <row>
3052        <entry>
3053         <indexterm>
3054          <primary>get_bit</primary>
3055         </indexterm>
3056         <literal><function>get_bit(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3057        </entry>
3058        <entry><type>int</type></entry>
3059        <entry>
3060         Extract bit from string
3061        </entry>
3062        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
3063        <entry><literal>1</literal></entry>
3064       </row>
3065
3066       <row>
3067        <entry>
3068         <indexterm>
3069          <primary>get_byte</primary>
3070         </indexterm>
3071         <literal><function>get_byte(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3072        </entry>
3073        <entry><type>int</type></entry>
3074        <entry>
3075         Extract byte from string
3076        </entry>
3077        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
3078        <entry><literal>109</literal></entry>
3079       </row>
3080
3081      <row>
3082       <entry>
3083        <indexterm>
3084         <primary>length</primary>
3085        </indexterm>
3086        <literal><function>length(<parameter>string</parameter>)</function></literal>
3087       </entry>
3088       <entry><type>int</type></entry>
3089       <entry>
3090        Length of binary string
3091        <indexterm>
3092         <primary>binary string</primary>
3093         <secondary>length</secondary>
3094        </indexterm>
3095        <indexterm>
3096         <primary>length</primary>
3097         <secondary sortas="binary string">of a binary string</secondary>
3098         <see>binary strings, length</see>
3099        </indexterm>
3100       </entry>
3101       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
3102       <entry><literal>5</literal></entry>
3103      </row>
3104
3105      <row>
3106       <entry>
3107        <indexterm>
3108         <primary>md5</primary>
3109        </indexterm>
3110        <literal><function>md5(<parameter>string</parameter>)</function></literal>
3111       </entry>
3112       <entry><type>text</type></entry>
3113       <entry>
3114        Calculates the MD5 hash of <parameter>string</parameter>,
3115        returning the result in hexadecimal
3116       </entry>
3117       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
3118       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
3119      </row>
3120
3121       <row>
3122        <entry>
3123         <indexterm>
3124          <primary>set_bit</primary>
3125         </indexterm>
3126         <literal><function>set_bit(<parameter>string</parameter>,
3127         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3128        </entry>
3129        <entry><type>bytea</type></entry>
3130        <entry>
3131         Set bit in string
3132        </entry>
3133        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
3134        <entry><literal>Th\000omAs</literal></entry>
3135       </row>
3136
3137       <row>
3138        <entry>
3139         <indexterm>
3140          <primary>set_byte</primary>
3141         </indexterm>
3142         <literal><function>set_byte(<parameter>string</parameter>,
3143         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3144        </entry>
3145        <entry><type>bytea</type></entry>
3146        <entry>
3147         Set byte in string
3148        </entry>
3149        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
3150        <entry><literal>Th\000o@as</literal></entry>
3151       </row>
3152     </tbody>
3153    </tgroup>
3154   </table>
3155
3156   <para>
3157    <function>get_byte</> and <function>set_byte</> number the first byte
3158    of a binary string as byte 0.
3159    <function>get_bit</> and <function>set_bit</> number bits from the
3160    right within each byte; for example bit 0 is the least significant bit of
3161    the first byte, and bit 15 is the most significant bit of the second byte.
3162   </para>
3163  </sect1>
3164
3165
3166   <sect1 id="functions-bitstring">
3167    <title>Bit String Functions and Operators</title>
3168
3169    <indexterm zone="functions-bitstring">
3170     <primary>bit strings</primary>
3171     <secondary>functions</secondary>
3172    </indexterm>
3173
3174    <para>
3175     This section describes functions and operators for examining and
3176     manipulating bit strings, that is values of the types
3177     <type>bit</type> and <type>bit varying</type>.  Aside from the
3178     usual comparison operators, the operators
3179     shown in <xref linkend="functions-bit-string-op-table"> can be used.
3180     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
3181     and <literal>#</literal> must be of equal length.  When bit
3182     shifting, the original length of the string is preserved, as shown
3183     in the examples.
3184    </para>
3185
3186    <table id="functions-bit-string-op-table">
3187     <title>Bit String Operators</title>
3188
3189     <tgroup cols="4">
3190      <thead>
3191       <row>
3192        <entry>Operator</entry>
3193        <entry>Description</entry>
3194        <entry>Example</entry>
3195        <entry>Result</entry>
3196       </row>
3197      </thead>
3198
3199      <tbody>
3200       <row>
3201        <entry> <literal>||</literal> </entry>
3202        <entry>concatenation</entry>
3203        <entry><literal>B'10001' || B'011'</literal></entry>
3204        <entry><literal>10001011</literal></entry>
3205       </row>
3206
3207       <row>
3208        <entry> <literal>&amp;</literal> </entry>
3209        <entry>bitwise AND</entry>
3210        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
3211        <entry><literal>00001</literal></entry>
3212       </row>
3213
3214       <row>
3215        <entry> <literal>|</literal> </entry>
3216        <entry>bitwise OR</entry>
3217        <entry><literal>B'10001' | B'01101'</literal></entry>
3218        <entry><literal>11101</literal></entry>
3219       </row>
3220
3221       <row>
3222        <entry> <literal>#</literal> </entry>
3223        <entry>bitwise XOR</entry>
3224        <entry><literal>B'10001' # B'01101'</literal></entry>
3225        <entry><literal>11100</literal></entry>
3226       </row>
3227
3228       <row>
3229        <entry> <literal>~</literal> </entry>
3230        <entry>bitwise NOT</entry>
3231        <entry><literal>~ B'10001'</literal></entry>
3232        <entry><literal>01110</literal></entry>
3233       </row>
3234
3235       <row>
3236        <entry> <literal>&lt;&lt;</literal> </entry>
3237        <entry>bitwise shift left</entry>
3238        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
3239        <entry><literal>01000</literal></entry>
3240       </row>
3241
3242       <row>
3243        <entry> <literal>&gt;&gt;</literal> </entry>
3244        <entry>bitwise shift right</entry>
3245        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
3246        <entry><literal>00100</literal></entry>
3247       </row>
3248      </tbody>
3249     </tgroup>
3250    </table>
3251
3252    <para>
3253     The following <acronym>SQL</acronym>-standard functions work on bit
3254     strings as well as character strings:
3255     <literal><function>length</function></literal>,
3256     <literal><function>bit_length</function></literal>,
3257     <literal><function>octet_length</function></literal>,
3258     <literal><function>position</function></literal>,
3259     <literal><function>substring</function></literal>,
3260     <literal><function>overlay</function></literal>.
3261    </para>
3262
3263    <para>
3264     The following functions work on bit strings as well as binary
3265     strings:
3266     <literal><function>get_bit</function></literal>,
3267     <literal><function>set_bit</function></literal>.
3268     When working with a bit string, these functions number the first
3269     (leftmost) bit of the string as bit 0.
3270    </para>
3271
3272    <para>
3273     In addition, it is possible to cast integral values to and from type
3274     <type>bit</>.
3275     Some examples:
3276 <programlisting>
3277 44::bit(10)                    <lineannotation>0000101100</lineannotation>
3278 44::bit(3)                     <lineannotation>100</lineannotation>
3279 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
3280 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
3281 </programlisting>
3282     Note that casting to just <quote>bit</> means casting to
3283     <literal>bit(1)</>, and so will deliver only the least significant
3284     bit of the integer.
3285    </para>
3286
3287     <note>
3288      <para>
3289       Prior to <productname>PostgreSQL</productname> 8.0, casting an
3290       integer to <type>bit(n)</> would copy the leftmost <literal>n</>
3291       bits of the integer, whereas now it copies the rightmost <literal>n</>
3292       bits.  Also, casting an integer to a bit string width wider than
3293       the integer itself will sign-extend on the left.
3294      </para>
3295     </note>
3296
3297   </sect1>
3298
3299
3300  <sect1 id="functions-matching">
3301   <title>Pattern Matching</title>
3302
3303   <indexterm zone="functions-matching">
3304    <primary>pattern matching</primary>
3305   </indexterm>
3306
3307    <para>
3308     There are three separate approaches to pattern matching provided
3309     by <productname>PostgreSQL</productname>: the traditional
3310     <acronym>SQL</acronym> <function>LIKE</function> operator, the
3311     more recent <function>SIMILAR TO</function> operator (added in
3312     SQL:1999), and <acronym>POSIX</acronym>-style regular
3313     expressions.  Aside from the basic <quote>does this string match
3314     this pattern?</> operators, functions are available to extract
3315     or replace matching substrings and to split a string at matching
3316     locations.
3317    </para>
3318
3319    <tip>
3320     <para>
3321      If you have pattern matching needs that go beyond this,
3322      consider writing a user-defined function in Perl or Tcl.
3323     </para>
3324    </tip>
3325
3326   <sect2 id="functions-like">
3327    <title><function>LIKE</function></title>
3328
3329    <indexterm>
3330     <primary>LIKE</primary>
3331    </indexterm>
3332
3333 <synopsis>
3334 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3335 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3336 </synopsis>
3337
3338     <para>
3339      The <function>LIKE</function> expression returns true if the
3340      <replaceable>string</replaceable> matches the supplied
3341      <replaceable>pattern</replaceable>.  (As
3342      expected, the <function>NOT LIKE</function> expression returns
3343      false if <function>LIKE</function> returns true, and vice versa.
3344      An equivalent expression is
3345      <literal>NOT (<replaceable>string</replaceable> LIKE
3346       <replaceable>pattern</replaceable>)</literal>.)
3347     </para>
3348
3349     <para>
3350      If <replaceable>pattern</replaceable> does not contain percent
3351      signs or underscores, then the pattern only represents the string
3352      itself; in that case <function>LIKE</function> acts like the
3353      equals operator.  An underscore (<literal>_</literal>) in
3354      <replaceable>pattern</replaceable> stands for (matches) any single
3355      character; a percent sign (<literal>%</literal>) matches any sequence
3356      of zero or more characters.
3357     </para>
3358
3359    <para>
3360     Some examples:
3361 <programlisting>
3362 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
3363 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
3364 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
3365 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
3366 </programlisting>
3367    </para>
3368
3369    <para>
3370     <function>LIKE</function> pattern matching always covers the entire
3371     string.  Therefore, to match a sequence anywhere within a string, the
3372     pattern must start and end with a percent sign.
3373    </para>
3374
3375    <para>
3376     To match a literal underscore or percent sign without matching
3377     other characters, the respective character in
3378     <replaceable>pattern</replaceable> must be
3379     preceded by the escape character.  The default escape
3380     character is the backslash but a different one can be selected by
3381     using the <literal>ESCAPE</literal> clause.  To match the escape
3382     character itself, write two escape characters.
3383    </para>
3384
3385    <para>
3386     Note that the backslash already has a special meaning in string literals,
3387     so to write a pattern constant that contains a backslash you must write two
3388     backslashes in an SQL statement (assuming escape string syntax is used, see
3389     <xref linkend="sql-syntax-strings">).  Thus, writing a pattern that
3390     actually matches a literal backslash means writing four backslashes in the
3391     statement.  You can avoid this by selecting a different escape character
3392     with <literal>ESCAPE</literal>; then a backslash is not special to
3393     <function>LIKE</function> anymore. (But backslash is still special to the
3394     string literal parser, so you still need two of them to match a backslash.)
3395    </para>
3396
3397    <para>
3398     It's also possible to select no escape character by writing
3399     <literal>ESCAPE ''</literal>.  This effectively disables the
3400     escape mechanism, which makes it impossible to turn off the
3401     special meaning of underscore and percent signs in the pattern.
3402    </para>
3403
3404    <para>
3405     The key word <token>ILIKE</token> can be used instead of
3406     <token>LIKE</token> to make the match case-insensitive according
3407     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3408     <productname>PostgreSQL</productname> extension.
3409    </para>
3410
3411    <para>
3412     The operator <literal>~~</literal> is equivalent to
3413     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3414     <function>ILIKE</function>.  There are also
3415     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3416     represent <function>NOT LIKE</function> and <function>NOT
3417     ILIKE</function>, respectively.  All of these operators are
3418     <productname>PostgreSQL</productname>-specific.
3419    </para>
3420   </sect2>
3421
3422
3423   <sect2 id="functions-similarto-regexp">
3424    <title><function>SIMILAR TO</function> Regular Expressions</title>
3425
3426    <indexterm>
3427     <primary>regular expression</primary>
3428     <!-- <seealso>pattern matching</seealso> breaks index build -->
3429    </indexterm>
3430
3431    <indexterm>
3432     <primary>SIMILAR TO</primary>
3433    </indexterm>
3434    <indexterm>
3435     <primary>substring</primary>
3436    </indexterm>
3437
3438 <synopsis>
3439 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3440 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3441 </synopsis>
3442
3443    <para>
3444     The <function>SIMILAR TO</function> operator returns true or
3445     false depending on whether its pattern matches the given string.
3446     It is similar to <function>LIKE</function>, except that it
3447     interprets the pattern using the SQL standard's definition of a
3448     regular expression.  SQL regular expressions are a curious cross
3449     between <function>LIKE</function> notation and common regular
3450     expression notation.
3451    </para>
3452
3453    <para>
3454     Like <function>LIKE</function>, the <function>SIMILAR TO</function>
3455     operator succeeds only if its pattern matches the entire string;
3456     this is unlike common regular expression behavior where the pattern
3457     can match any part of the string.
3458     Also like
3459     <function>LIKE</function>, <function>SIMILAR TO</function> uses
3460     <literal>_</> and <literal>%</> as wildcard characters denoting
3461     any single character and any string, respectively (these are
3462     comparable to <literal>.</> and <literal>.*</> in POSIX regular
3463     expressions).
3464    </para>
3465
3466    <para>
3467     In addition to these facilities borrowed from <function>LIKE</function>,
3468     <function>SIMILAR TO</function> supports these pattern-matching
3469     metacharacters borrowed from POSIX regular expressions:
3470
3471    <itemizedlist>
3472     <listitem>
3473      <para>
3474       <literal>|</literal> denotes alternation (either of two alternatives).
3475      </para>
3476     </listitem>
3477     <listitem>
3478      <para>
3479       <literal>*</literal> denotes repetition of the previous item zero
3480       or more times.
3481      </para>
3482     </listitem>
3483     <listitem>
3484      <para>
3485       <literal>+</literal> denotes repetition of the previous item one
3486       or more times.
3487      </para>
3488     </listitem>
3489     <listitem>
3490      <para>
3491       <literal>?</literal> denotes repetition of the previous item zero
3492       or one time.
3493      </para>
3494     </listitem>
3495     <listitem>
3496      <para>
3497       <literal>{</><replaceable>m</><literal>}</literal> denotes repetition
3498       of the previous item exactly <replaceable>m</> times.
3499      </para>
3500     </listitem>
3501     <listitem>
3502      <para>
3503       <literal>{</><replaceable>m</><literal>,}</literal> denotes repetition
3504       of the previous item <replaceable>m</> or more times.
3505      </para>
3506     </listitem>
3507     <listitem>
3508      <para>
3509       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
3510       denotes repetition of the previous item at least <replaceable>m</> and
3511       not more than <replaceable>n</> times.
3512      </para>
3513     </listitem>
3514     <listitem>
3515      <para>
3516       Parentheses <literal>()</literal> can be used to group items into
3517       a single logical item.
3518      </para>
3519     </listitem>
3520     <listitem>
3521      <para>
3522       A bracket expression <literal>[...]</literal> specifies a character
3523       class, just as in POSIX regular expressions.
3524      </para>
3525     </listitem>
3526    </itemizedlist>
3527
3528     Notice that the period (<literal>.</>) is not a metacharacter
3529     for <function>SIMILAR TO</>.
3530    </para>
3531
3532    <para>
3533     As with <function>LIKE</>, a backslash disables the special meaning
3534     of any of these metacharacters; or a different escape character can
3535     be specified with <literal>ESCAPE</>.
3536    </para>
3537
3538    <para>
3539     Some examples:
3540 <programlisting>
3541 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
3542 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
3543 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
3544 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
3545 </programlisting>
3546    </para>
3547
3548    <para>
3549     The <function>substring</> function with three parameters,
3550     <function>substring(<replaceable>string</replaceable> from
3551     <replaceable>pattern</replaceable> for
3552     <replaceable>escape-character</replaceable>)</function>, provides
3553     extraction of a substring that matches an SQL
3554     regular expression pattern.  As with <literal>SIMILAR TO</>, the
3555     specified pattern must match the entire data string, or else the
3556     function fails and returns null.  To indicate the part of the
3557     pattern that should be returned on success, the pattern must contain
3558     two occurrences of the escape character followed by a double quote
3559     (<literal>"</>). <!-- " font-lock sanity -->
3560     The text matching the portion of the pattern
3561     between these markers is returned.
3562    </para>
3563
3564    <para>
3565     Some examples, with <literal>#&quot;</> delimiting the return string:
3566 <programlisting>
3567 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
3568 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
3569 </programlisting>
3570    </para>
3571   </sect2>
3572
3573   <sect2 id="functions-posix-regexp">
3574    <title><acronym>POSIX</acronym> Regular Expressions</title>
3575
3576    <indexterm zone="functions-posix-regexp">
3577     <primary>regular expression</primary>
3578     <seealso>pattern matching</seealso>
3579    </indexterm>
3580    <indexterm>
3581     <primary>substring</primary>
3582    </indexterm>
3583    <indexterm>
3584     <primary>regexp_replace</primary>
3585    </indexterm>
3586    <indexterm>
3587     <primary>regexp_matches</primary>
3588    </indexterm>
3589    <indexterm>
3590     <primary>regexp_split_to_table</primary>
3591    </indexterm>
3592    <indexterm>
3593     <primary>regexp_split_to_array</primary>
3594    </indexterm>
3595
3596    <para>
3597     <xref linkend="functions-posix-table"> lists the available
3598     operators for pattern matching using POSIX regular expressions.
3599    </para>
3600
3601    <table id="functions-posix-table">
3602     <title>Regular Expression Match Operators</title>
3603
3604     <tgroup cols="3">
3605      <thead>
3606       <row>
3607        <entry>Operator</entry>
3608        <entry>Description</entry>
3609        <entry>Example</entry>
3610       </row>
3611      </thead>
3612
3613       <tbody>
3614        <row>
3615         <entry> <literal>~</literal> </entry>
3616         <entry>Matches regular expression, case sensitive</entry>
3617         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3618        </row>
3619
3620        <row>
3621         <entry> <literal>~*</literal> </entry>
3622         <entry>Matches regular expression, case insensitive</entry>
3623         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3624        </row>
3625
3626        <row>
3627         <entry> <literal>!~</literal> </entry>
3628         <entry>Does not match regular expression, case sensitive</entry>
3629         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3630        </row>
3631
3632        <row>
3633         <entry> <literal>!~*</literal> </entry>
3634         <entry>Does not match regular expression, case insensitive</entry>
3635         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3636        </row>
3637       </tbody>
3638      </tgroup>
3639     </table>
3640
3641     <para>
3642      <acronym>POSIX</acronym> regular expressions provide a more
3643      powerful means for pattern matching than the <function>LIKE</function> and
3644      <function>SIMILAR TO</> operators.
3645      Many Unix tools such as <command>egrep</command>,
3646      <command>sed</command>, or <command>awk</command> use a pattern
3647      matching language that is similar to the one described here.
3648     </para>
3649
3650     <para>
3651      A regular expression is a character sequence that is an
3652      abbreviated definition of a set of strings (a <firstterm>regular
3653      set</firstterm>).  A string is said to match a regular expression
3654      if it is a member of the regular set described by the regular
3655      expression.  As with <function>LIKE</function>, pattern characters
3656      match string characters exactly unless they are special characters
3657      in the regular expression language &mdash; but regular expressions use
3658      different special characters than <function>LIKE</function> does.
3659      Unlike <function>LIKE</function> patterns, a
3660      regular expression is allowed to match anywhere within a string, unless
3661      the regular expression is explicitly anchored to the beginning or
3662      end of the string.
3663     </para>
3664
3665     <para>
3666      Some examples:
3667 <programlisting>
3668 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
3669 'abc' ~ '^a'     <lineannotation>true</lineannotation>
3670 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
3671 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3672 </programlisting>
3673     </para>
3674
3675     <para>
3676      The <acronym>POSIX</acronym> pattern language is described in much
3677      greater detail below.
3678     </para>
3679
3680     <para>
3681      The <function>substring</> function with two parameters,
3682      <function>substring(<replaceable>string</replaceable> from
3683      <replaceable>pattern</replaceable>)</function>, provides extraction of a
3684      substring
3685      that matches a POSIX regular expression pattern.  It returns null if
3686      there is no match, otherwise the portion of the text that matched the
3687      pattern.  But if the pattern contains any parentheses, the portion
3688      of the text that matched the first parenthesized subexpression (the
3689      one whose left parenthesis comes first) is
3690      returned.  You can put parentheses around the whole expression
3691      if you want to use parentheses within it without triggering this
3692      exception.  If you need parentheses in the pattern before the
3693      subexpression you want to extract, see the non-capturing parentheses
3694      described below.
3695     </para>
3696
3697    <para>
3698     Some examples:
3699 <programlisting>
3700 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
3701 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
3702 </programlisting>
3703    </para>
3704
3705     <para>
3706      The <function>regexp_replace</> function provides substitution of
3707      new text for substrings that match POSIX regular expression patterns.
3708      It has the syntax
3709      <function>regexp_replace</function>(<replaceable>source</>,
3710      <replaceable>pattern</>, <replaceable>replacement</>
3711      <optional>, <replaceable>flags</> </optional>).
3712      The <replaceable>source</> string is returned unchanged if
3713      there is no match to the <replaceable>pattern</>.  If there is a
3714      match, the <replaceable>source</> string is returned with the
3715      <replaceable>replacement</> string substituted for the matching
3716      substring.  The <replaceable>replacement</> string can contain
3717      <literal>\</><replaceable>n</>, where <replaceable>n</> is 1
3718      through 9, to indicate that the source substring matching the
3719      <replaceable>n</>'th parenthesized subexpression of the pattern should be
3720      inserted, and it can contain <literal>\&amp;</> to indicate that the
3721      substring matching the entire pattern should be inserted.  Write
3722      <literal>\\</> if you need to put a literal backslash in the replacement
3723      text.  (As always, remember to double backslashes written in literal
3724      constant strings, assuming escape string syntax is used.)
3725      The <replaceable>flags</> parameter is an optional text
3726      string containing zero or more single-letter flags that change the
3727      function's behavior.  Flag <literal>i</> specifies case-insensitive
3728      matching, while flag <literal>g</> specifies replacement of each matching
3729      substring rather than only the first one.  Other supported flags are
3730      described in <xref linkend="posix-embedded-options-table">.
3731     </para>
3732
3733    <para>
3734     Some examples:
3735 <programlisting>
3736 regexp_replace('foobarbaz', 'b..', 'X')
3737                                    <lineannotation>fooXbaz</lineannotation>
3738 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3739                                    <lineannotation>fooXX</lineannotation>
3740 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3741                                    <lineannotation>fooXarYXazY</lineannotation>
3742 </programlisting>
3743    </para>
3744
3745     <para>
3746      The <function>regexp_matches</> function returns a text array of
3747      all of the captured substrings resulting from matching a POSIX
3748      regular expression pattern.  It has the syntax
3749      <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3750      <optional>, <replaceable>flags</> </optional>).
3751      The function can return no rows, one row, or multiple rows (see
3752      the <literal>g</> flag below).  If the <replaceable>pattern</>
3753      does not match, the function returns no rows.  If the pattern
3754      contains no parenthesized subexpressions, then each row
3755      returned is a single-element text array containing the substring
3756      matching the whole pattern.  If the pattern contains parenthesized
3757      subexpressions, the function returns a text array whose
3758      <replaceable>n</>'th element is the substring matching the
3759      <replaceable>n</>'th parenthesized subexpression of the pattern
3760      (not counting <quote>non-capturing</> parentheses; see below for
3761      details).
3762      The <replaceable>flags</> parameter is an optional text
3763      string containing zero or more single-letter flags that change the
3764      function's behavior.  Flag <literal>g</> causes the function to find
3765      each match in the string, not only the first one, and return a row for
3766      each such match.  Other supported
3767      flags are described in <xref linkend="posix-embedded-options-table">.
3768     </para>
3769
3770    <para>
3771     Some examples:
3772 <programlisting>
3773 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3774  regexp_matches 
3775 ----------------
3776  {bar,beque}
3777 (1 row)
3778
3779 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3780  regexp_matches 
3781 ----------------
3782  {bar,beque}
3783  {bazil,barf}
3784 (2 rows)
3785
3786 SELECT regexp_matches('foobarbequebaz', 'barbeque');
3787  regexp_matches 
3788 ----------------
3789  {barbeque}
3790 (1 row)
3791 </programlisting>
3792    </para>
3793
3794    <para>
3795     It is possible to force <function>regexp_matches()</> to always
3796     return one row by using a sub-select;  this is particularly useful
3797     in a <literal>SELECT</> target list when you want all rows
3798     returned, even non-matching ones:
3799 <programlisting>
3800 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
3801 </programlisting>
3802    </para>
3803
3804     <para>
3805      The <function>regexp_split_to_table</> function splits a string using a POSIX
3806      regular expression pattern as a delimiter.  It has the syntax
3807      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
3808      <optional>, <replaceable>flags</> </optional>).
3809      If there is no match to the <replaceable>pattern</>, the function returns the
3810      <replaceable>string</>.  If there is at least one match, for each match it returns
3811      the text from the end of the last match (or the beginning of the string)
3812      to the beginning of the match.  When there are no more matches, it
3813      returns the text from the end of the last match to the end of the string.
3814      The <replaceable>flags</> parameter is an optional text string containing
3815      zero or more single-letter flags that change the function's behavior.
3816      <function>regexp_split_to_table</function> supports the flags described in
3817      <xref linkend="posix-embedded-options-table">.
3818     </para>
3819
3820     <para>
3821      The <function>regexp_split_to_array</> function behaves the same as
3822      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
3823      returns its result as an array of <type>text</>.  It has the syntax
3824      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
3825      <optional>, <replaceable>flags</> </optional>).
3826      The parameters are the same as for <function>regexp_split_to_table</>.
3827     </para>
3828
3829    <para>
3830     Some examples:
3831 <programlisting>
3832
3833 SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\s+') AS foo;
3834   foo   
3835 --------
3836  the    
3837  quick  
3838  brown  
3839  fox    
3840  jumped 
3841  over   
3842  the    
3843  lazy   
3844  dog    
3845 (9 rows)
3846
3847 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
3848               regexp_split_to_array             
3849 ------------------------------------------------
3850  {the,quick,brown,fox,jumped,over,the,lazy,dog}
3851 (1 row)
3852
3853 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
3854  foo 
3855 -----
3856  t         
3857  h         
3858  e         
3859  q         
3860  u         
3861  i         
3862  c         
3863  k         
3864  b         
3865  r         
3866  o         
3867  w         
3868  n         
3869  f         
3870  o         
3871  x         
3872 (16 rows)
3873 </programlisting>
3874    </para>
3875
3876    <para>
3877     As the last example demonstrates, the regexp split functions ignore
3878     zero-length matches that occur at the start or end of the string
3879     or immediately after a previous match.  This is contrary to the strict
3880     definition of regexp matching that is implemented by
3881     <function>regexp_matches</>, but is usually the most convenient behavior
3882     in practice.  Other software systems such as Perl use similar definitions.
3883    </para>
3884
3885 <!-- derived from the re_syntax.n man page -->
3886
3887    <sect3 id="posix-syntax-details">
3888     <title>Regular Expression Details</title>
3889
3890    <para>
3891     <productname>PostgreSQL</productname>'s regular expressions are implemented
3892     using a software package written by Henry Spencer.  Much of
3893     the description of regular expressions below is copied verbatim from his
3894     manual.
3895    </para>
3896
3897    <para>
3898     Regular expressions (<acronym>RE</acronym>s), as defined in
3899     <acronym>POSIX</acronym> 1003.2, come in two forms:
3900     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
3901     (roughly those of <command>egrep</command>), and
3902     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
3903     (roughly those of <command>ed</command>).
3904     <productname>PostgreSQL</productname> supports both forms, and
3905     also implements some extensions
3906     that are not in the POSIX standard, but have become widely used
3907     due to their availability in programming languages such as Perl and Tcl.
3908     <acronym>RE</acronym>s using these non-POSIX extensions are called
3909     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
3910     in this documentation.  AREs are almost an exact superset of EREs,
3911     but BREs have several notational incompatibilities (as well as being
3912     much more limited).
3913     We first describe the ARE and ERE forms, noting features that apply
3914     only to AREs, and then describe how BREs differ.
3915    </para>
3916
3917    <note>
3918     <para>
3919      <productname>PostgreSQL</> always initially presumes that a regular
3920      expression follows the ARE rules.  However, the more limited ERE or
3921      BRE rules can be chosen by prepending an <firstterm>embedded option</>
3922      to the RE pattern, as described in <xref linkend="posix-metasyntax">.
3923      This can be useful for compatibility with applications that expect
3924      exactly the <acronym>POSIX</acronym> 1003.2 rules.
3925     </para>
3926    </note>
3927
3928    <para>
3929     A regular expression is defined as one or more
3930     <firstterm>branches</firstterm>, separated by
3931     <literal>|</literal>.  It matches anything that matches one of the
3932     branches.
3933    </para>
3934
3935    <para>
3936     A branch is zero or more <firstterm>quantified atoms</> or
3937     <firstterm>constraints</>, concatenated.
3938     It matches a match for the first, followed by a match for the second, etc;
3939     an empty branch matches the empty string.
3940    </para>
3941
3942    <para>
3943     A quantified atom is an <firstterm>atom</> possibly followed
3944     by a single <firstterm>quantifier</>.
3945     Without a quantifier, it matches a match for the atom.
3946     With a quantifier, it can match some number of matches of the atom.
3947     An <firstterm>atom</firstterm> can be any of the possibilities
3948     shown in <xref linkend="posix-atoms-table">.
3949     The possible quantifiers and their meanings are shown in
3950     <xref linkend="posix-quantifiers-table">.
3951    </para>
3952
3953    <para>
3954     A <firstterm>constraint</> matches an empty string, but matches only when
3955     specific conditions are met.  A constraint can be used where an atom
3956     could be used, except it cannot be followed by a quantifier.
3957     The simple constraints are shown in
3958     <xref linkend="posix-constraints-table">;
3959     some more constraints are described later.
3960    </para>
3961
3962
3963    <table id="posix-atoms-table">
3964     <title>Regular Expression Atoms</title>
3965
3966     <tgroup cols="2">
3967      <thead>
3968       <row>
3969        <entry>Atom</entry>
3970        <entry>Description</entry>
3971       </row>
3972      </thead>
3973
3974       <tbody>
3975        <row>
3976        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3977        <entry> (where <replaceable>re</> is any regular expression)
3978        matches a match for
3979        <replaceable>re</>, with the match noted for possible reporting </entry>
3980        </row>
3981
3982        <row>
3983        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3984        <entry> as above, but the match is not noted for reporting
3985        (a <quote>non-capturing</> set of parentheses)
3986        (AREs only) </entry>
3987        </row>
3988
3989        <row>
3990        <entry> <literal>.</> </entry>
3991        <entry> matches any single character </entry>
3992        </row>
3993
3994        <row>
3995        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
3996        <entry> a <firstterm>bracket expression</>,
3997        matching any one of the <replaceable>chars</> (see
3998        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
3999        </row>
4000
4001        <row>
4002        <entry> <literal>\</><replaceable>k</> </entry>
4003        <entry> (where <replaceable>k</> is a non-alphanumeric character)
4004        matches that character taken as an ordinary character,
4005        e.g., <literal>\\</> matches a backslash character </entry>
4006        </row>
4007
4008        <row>
4009        <entry> <literal>\</><replaceable>c</> </entry>
4010        <entry> where <replaceable>c</> is alphanumeric
4011        (possibly followed by other characters)
4012        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
4013        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
4014        </row>
4015
4016        <row>
4017        <entry> <literal>{</> </entry>
4018        <entry> when followed by a character other than a digit,
4019        matches the left-brace character <literal>{</>;
4020        when followed by a digit, it is the beginning of a
4021        <replaceable>bound</> (see below) </entry>
4022        </row>
4023
4024        <row>
4025        <entry> <replaceable>x</> </entry>
4026        <entry> where <replaceable>x</> is a single character with no other
4027        significance, matches that character </entry>
4028        </row>
4029       </tbody>
4030      </tgroup>
4031     </table>
4032
4033    <para>
4034     An RE cannot end with <literal>\</>.
4035    </para>
4036
4037    <note>
4038     <para>
4039      Remember that the backslash (<literal>\</literal>) already has a special
4040      meaning in <productname>PostgreSQL</> string literals.
4041      To write a pattern constant that contains a backslash,
4042      you must write two backslashes in the statement, assuming escape
4043      string syntax is used (see <xref linkend="sql-syntax-strings">).
4044     </para>
4045    </note>
4046
4047    <table id="posix-quantifiers-table">
4048     <title>Regular Expression Quantifiers</title>
4049
4050     <tgroup cols="2">
4051      <thead>
4052       <row>
4053        <entry>Quantifier</entry>
4054        <entry>Matches</entry>
4055       </row>
4056      </thead>
4057
4058       <tbody>
4059        <row>
4060        <entry> <literal>*</> </entry>
4061        <entry> a sequence of 0 or more matches of the atom </entry>
4062        </row>
4063
4064        <row>
4065        <entry> <literal>+</> </entry>
4066        <entry> a sequence of 1 or more matches of the atom </entry>
4067        </row>
4068
4069        <row>
4070        <entry> <literal>?</> </entry>
4071        <entry> a sequence of 0 or 1 matches of the atom </entry>
4072        </row>
4073
4074        <row>
4075        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
4076        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
4077        </row>
4078
4079        <row>
4080        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
4081        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
4082        </row>
4083
4084        <row>
4085        <entry>
4086        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4087        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
4088        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
4089        <replaceable>n</> </entry>
4090        </row>
4091
4092        <row>
4093        <entry> <literal>*?</> </entry>
4094        <entry> non-greedy version of <literal>*</> </entry>
4095        </row>
4096
4097        <row>
4098        <entry> <literal>+?</> </entry>
4099        <entry> non-greedy version of <literal>+</> </entry>
4100        </row>
4101
4102        <row>
4103        <entry> <literal>??</> </entry>
4104        <entry> non-greedy version of <literal>?</> </entry>
4105        </row>
4106
4107        <row>
4108        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
4109        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
4110        </row>
4111
4112        <row>
4113        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
4114        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
4115        </row>
4116
4117        <row>
4118        <entry>
4119        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
4120        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4121        </row>
4122       </tbody>
4123      </tgroup>
4124     </table>
4125
4126    <para>
4127     The forms using <literal>{</><replaceable>...</><literal>}</>
4128     are known as <firstterm>bounds</>.
4129     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
4130     unsigned decimal integers with permissible values from 0 to 255 inclusive.
4131    </para>
4132
4133     <para>
4134      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
4135      same possibilities as their corresponding normal (<firstterm>greedy</>)
4136      counterparts, but prefer the smallest number rather than the largest
4137      number of matches.
4138      See <xref linkend="posix-matching-rules"> for more detail.
4139    </para>
4140
4141    <note>
4142     <para>
4143      A quantifier cannot immediately follow another quantifier, e.g.,
4144      <literal>**</> is invalid.
4145      A quantifier cannot
4146      begin an expression or subexpression or follow
4147      <literal>^</literal> or <literal>|</literal>.
4148     </para>
4149    </note>
4150
4151    <table id="posix-constraints-table">
4152     <title>Regular Expression Constraints</title>
4153
4154     <tgroup cols="2">
4155      <thead>
4156       <row>
4157        <entry>Constraint</entry>
4158        <entry>Description</entry>
4159       </row>
4160      </thead>
4161
4162       <tbody>
4163        <row>
4164        <entry> <literal>^</> </entry>
4165        <entry> matches at the beginning of the string </entry>
4166        </row>
4167
4168        <row>
4169        <entry> <literal>$</> </entry>
4170        <entry> matches at the end of the string </entry>
4171        </row>
4172
4173        <row>
4174        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
4175        <entry> <firstterm>positive lookahead</> matches at any point
4176        where a substring matching <replaceable>re</> begins
4177        (AREs only) </entry>
4178        </row>
4179
4180        <row>
4181        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
4182        <entry> <firstterm>negative lookahead</> matches at any point
4183        where no substring matching <replaceable>re</> begins
4184        (AREs only) </entry>
4185        </row>
4186       </tbody>
4187      </tgroup>
4188     </table>
4189
4190    <para>
4191     Lookahead constraints cannot contain <firstterm>back references</>
4192     (see <xref linkend="posix-escape-sequences">),
4193     and all parentheses within them are considered non-capturing.
4194    </para>
4195    </sect3>
4196
4197    <sect3 id="posix-bracket-expressions">
4198     <title>Bracket Expressions</title>
4199
4200    <para>
4201     A <firstterm>bracket expression</firstterm> is a list of
4202     characters enclosed in <literal>[]</literal>.  It normally matches
4203     any single character from the list (but see below).  If the list
4204     begins with <literal>^</literal>, it matches any single character
4205     <emphasis>not</> from the rest of the list.
4206     If two characters
4207     in the list are separated by <literal>-</literal>, this is
4208     shorthand for the full range of characters between those two
4209     (inclusive) in the collating sequence,
4210     e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
4211     any decimal digit.  It is illegal for two ranges to share an
4212     endpoint, e.g.,  <literal>a-c-e</literal>.  Ranges are very
4213     collating-sequence-dependent, so portable programs should avoid
4214     relying on them.
4215    </para>
4216
4217    <para>
4218     To include a literal <literal>]</literal> in the list, make it the
4219     first character (after <literal>^</literal>, if that is used).  To
4220     include a literal <literal>-</literal>, make it the first or last
4221     character, or the second endpoint of a range.  To use a literal
4222     <literal>-</literal> as the first endpoint of a range, enclose it
4223     in <literal>[.</literal> and <literal>.]</literal> to make it a
4224     collating element (see below).  With the exception of these characters,
4225     some combinations using <literal>[</literal>
4226     (see next paragraphs), and escapes (AREs only), all other special
4227     characters lose their special significance within a bracket expression.
4228     In particular, <literal>\</literal> is not special when following
4229     ERE or BRE rules, though it is special (as introducing an escape)
4230     in AREs.
4231    </para>
4232
4233    <para>
4234     Within a bracket expression, a collating element (a character, a
4235     multiple-character sequence that collates as if it were a single
4236     character, or a collating-sequence name for either) enclosed in
4237     <literal>[.</literal> and <literal>.]</literal> stands for the
4238     sequence of characters of that collating element.  The sequence is
4239     treated as a single element of the bracket expression's list.  This
4240     allows a bracket
4241     expression containing a multiple-character collating element to
4242     match more than one character, e.g., if the collating sequence
4243     includes a <literal>ch</literal> collating element, then the RE
4244     <literal>[[.ch.]]*c</literal> matches the first five characters of
4245     <literal>chchcc</literal>.
4246    </para>
4247
4248    <note>
4249     <para>
4250      <productname>PostgreSQL</> currently does not support multi-character collating
4251      elements. This information describes possible future behavior.
4252     </para>
4253    </note>
4254
4255    <para>
4256     Within a bracket expression, a collating element enclosed in
4257     <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
4258     class</>, standing for the sequences of characters of all collating
4259     elements equivalent to that one, including itself.  (If there are
4260     no other equivalent collating elements, the treatment is as if the
4261     enclosing delimiters were <literal>[.</literal> and
4262     <literal>.]</literal>.)  For example, if <literal>o</literal> and
4263     <literal>^</literal> are the members of an equivalence class, then
4264     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
4265     <literal>[o^]</literal> are all synonymous.  An equivalence class
4266     cannot be an endpoint of a range.
4267    </para>
4268
4269    <para>
4270     Within a bracket expression, the name of a character class
4271     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
4272     for the list of all characters belonging to that class.  Standard
4273     character class names are: <literal>alnum</literal>,
4274     <literal>alpha</literal>, <literal>blank</literal>,
4275     <literal>cntrl</literal>, <literal>digit</literal>,
4276     <literal>graph</literal>, <literal>lower</literal>,
4277     <literal>print</literal>, <literal>punct</literal>,
4278     <literal>space</literal>, <literal>upper</literal>,
4279     <literal>xdigit</literal>.  These stand for the character classes
4280     defined in
4281     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
4282     A locale can provide others.  A character class cannot be used as
4283     an endpoint of a range.
4284    </para>
4285
4286    <para>
4287     There are two special cases of bracket expressions:  the bracket
4288     expressions <literal>[[:&lt;:]]</literal> and
4289     <literal>[[:&gt;:]]</literal> are constraints,
4290     matching empty strings at the beginning
4291     and end of a word respectively.  A word is defined as a sequence
4292     of word characters that is neither preceded nor followed by word
4293     characters.  A word character is an <literal>alnum</> character (as
4294     defined by
4295     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
4296     or an underscore.  This is an extension, compatible with but not
4297     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
4298     caution in software intended to be portable to other systems.
4299     The constraint escapes described below are usually preferable; they
4300     are no more standard, but are easier to type.
4301    </para>
4302    </sect3>
4303
4304    <sect3 id="posix-escape-sequences">
4305     <title>Regular Expression Escapes</title>
4306
4307    <para>
4308     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
4309     followed by an alphanumeric character. Escapes come in several varieties:
4310     character entry, class shorthands, constraint escapes, and back references.
4311     A <literal>\</> followed by an alphanumeric character but not constituting
4312     a valid escape is illegal in AREs.
4313     In EREs, there are no escapes: outside a bracket expression,
4314     a <literal>\</> followed by an alphanumeric character merely stands for
4315     that character as an ordinary character, and inside a bracket expression,
4316     <literal>\</> is an ordinary character.
4317     (The latter is the one actual incompatibility between EREs and AREs.)
4318    </para>
4319
4320    <para>
4321     <firstterm>Character-entry escapes</> exist to make it easier to specify
4322     non-printing and other inconvenient characters in REs.  They are
4323     shown in <xref linkend="posix-character-entry-escapes-table">.
4324    </para>
4325
4326    <para>
4327     <firstterm>Class-shorthand escapes</> provide shorthands for certain
4328     commonly-used character classes.  They are
4329     shown in <xref linkend="posix-class-shorthand-escapes-table">.
4330    </para>
4331
4332    <para>
4333     A <firstterm>constraint escape</> is a constraint,
4334     matching the empty string if specific conditions are met,
4335     written as an escape.  They are
4336     shown in <xref linkend="posix-constraint-escapes-table">.
4337    </para>
4338
4339    <para>
4340     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
4341     same string matched by the previous parenthesized subexpression specified
4342     by the number <replaceable>n</>
4343     (see <xref linkend="posix-constraint-backref-table">).  For example,
4344     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
4345     but not <literal>bc</> or <literal>cb</>.
4346     The subexpression must entirely precede the back reference in the RE.
4347     Subexpressions are numbered in the order of their leading parentheses.
4348     Non-capturing parentheses do not define subexpressions.
4349    </para>
4350
4351    <note>
4352     <para>
4353      Keep in mind that an escape's leading <literal>\</> will need to be
4354      doubled when entering the pattern as an SQL string constant.  For example:
4355 <programlisting>
4356 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
4357 </programlisting>
4358     </para>
4359    </note>
4360
4361    <table id="posix-character-entry-escapes-table">
4362     <title>Regular Expression Character-entry Escapes</title>
4363
4364     <tgroup cols="2">
4365      <thead>
4366       <row>
4367        <entry>Escape</entry>
4368        <entry>Description</entry>
4369       </row>
4370      </thead>
4371
4372       <tbody>
4373        <row>
4374        <entry> <literal>\a</> </entry>
4375        <entry> alert (bell) character, as in C </entry>
4376        </row>
4377
4378        <row>
4379        <entry> <literal>\b</> </entry>
4380        <entry> backspace, as in C </entry>
4381        </row>
4382
4383        <row>
4384        <entry> <literal>\B</> </entry>
4385        <entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
4386        doubling </entry>
4387        </row>
4388
4389        <row>
4390        <entry> <literal>\c</><replaceable>X</> </entry>
4391        <entry> (where <replaceable>X</> is any character) the character whose
4392        low-order 5 bits are the same as those of
4393        <replaceable>X</>, and whose other bits are all zero </entry>
4394        </row>
4395
4396        <row>
4397        <entry> <literal>\e</> </entry>
4398        <entry> the character whose collating-sequence name
4399        is <literal>ESC</>,
4400        or failing that, the character with octal value 033 </entry>
4401        </row>
4402
4403        <row>
4404        <entry> <literal>\f</> </entry>
4405        <entry> form feed, as in C </entry>
4406        </row>
4407
4408        <row>
4409        <entry> <literal>\n</> </entry>
4410        <entry> newline, as in C </entry>
4411        </row>
4412
4413        <row>
4414        <entry> <literal>\r</> </entry>
4415        <entry> carriage return, as in C </entry>
4416        </row>
4417
4418        <row>
4419        <entry> <literal>\t</> </entry>
4420        <entry> horizontal tab, as in C </entry>
4421        </row>
4422
4423        <row>
4424        <entry> <literal>\u</><replaceable>wxyz</> </entry>
4425        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4426        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4427        in the local byte ordering </entry>
4428        </row>
4429
4430        <row>
4431        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4432        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4433        digits)
4434        reserved for a hypothetical Unicode extension to 32 bits
4435        </entry>
4436        </row>
4437
4438        <row>
4439        <entry> <literal>\v</> </entry>
4440        <entry> vertical tab, as in C </entry>
4441        </row>
4442
4443        <row>
4444        <entry> <literal>\x</><replaceable>hhh</> </entry>
4445        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4446        digits)
4447        the character whose hexadecimal value is
4448        <literal>0x</><replaceable>hhh</>
4449        (a single character no matter how many hexadecimal digits are used)
4450        </entry>
4451        </row>
4452
4453        <row>
4454        <entry> <literal>\0</> </entry>
4455        <entry> the character whose value is <literal>0</> (the null byte)</entry>
4456        </row>
4457
4458        <row>
4459        <entry> <literal>\</><replaceable>xy</> </entry>
4460        <entry> (where <replaceable>xy</> is exactly two octal digits,
4461        and is not a <firstterm>back reference</>)
4462        the character whose octal value is
4463        <literal>0</><replaceable>xy</> </entry>
4464        </row>
4465
4466        <row>
4467        <entry> <literal>\</><replaceable>xyz</> </entry>
4468        <entry> (where <replaceable>xyz</> is exactly three octal digits,
4469        and is not a <firstterm>back reference</>)
4470        the character whose octal value is
4471        <literal>0</><replaceable>xyz</> </entry>
4472        </row>
4473       </tbody>
4474      </tgroup>
4475     </table>
4476
4477    <para>
4478     Hexadecimal digits are <literal>0</>-<literal>9</>,
4479     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4480     Octal digits are <literal>0</>-<literal>7</>.
4481    </para>
4482
4483    <para>
4484     The character-entry escapes are always taken as ordinary characters.
4485     For example, <literal>\135</> is <literal>]</> in ASCII, but
4486     <literal>\135</> does not terminate a bracket expression.
4487    </para>
4488
4489    <table id="posix-class-shorthand-escapes-table">
4490     <title>Regular Expression Class-shorthand Escapes</title>
4491
4492     <tgroup cols="2">
4493      <thead>
4494       <row>
4495        <entry>Escape</entry>
4496        <entry>Description</entry>
4497       </row>
4498      </thead>
4499
4500       <tbody>
4501        <row>
4502        <entry> <literal>\d</> </entry>
4503        <entry> <literal>[[:digit:]]</> </entry>
4504        </row>
4505
4506        <row>
4507        <entry> <literal>\s</> </entry>
4508        <entry> <literal>[[:space:]]</> </entry>
4509        </row>
4510
4511        <row>
4512        <entry> <literal>\w</> </entry>
4513        <entry> <literal>[[:alnum:]_]</>
4514        (note underscore is included) </entry>
4515        </row>
4516
4517        <row>
4518        <entry> <literal>\D</> </entry>
4519        <entry> <literal>[^[:digit:]]</> </entry>
4520        </row>
4521
4522        <row>
4523        <entry> <literal>\S</> </entry>
4524        <entry> <literal>[^[:space:]]</> </entry>
4525        </row>
4526
4527        <row>
4528        <entry> <literal>\W</> </entry>
4529        <entry> <literal>[^[:alnum:]_]</>
4530        (note underscore is included) </entry>
4531        </row>
4532       </tbody>
4533      </tgroup>
4534     </table>
4535
4536    <para>
4537     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4538     and <literal>\w</> lose their outer brackets,
4539     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4540     (So, for example, <literal>[a-c\d]</> is equivalent to
4541     <literal>[a-c[:digit:]]</>.
4542     Also, <literal>[a-c\D]</>, which is equivalent to
4543     <literal>[a-c^[:digit:]]</>, is illegal.)
4544    </para>
4545
4546    <table id="posix-constraint-escapes-table">
4547     <title>Regular Expression Constraint Escapes</title>
4548
4549     <tgroup cols="2">
4550      <thead>
4551       <row>
4552        <entry>Escape</entry>
4553        <entry>Description</entry>
4554       </row>
4555      </thead>
4556
4557       <tbody>
4558        <row>
4559        <entry> <literal>\A</> </entry>
4560        <entry> matches only at the beginning of the string
4561        (see <xref linkend="posix-matching-rules"> for how this differs from
4562        <literal>^</>) </entry>
4563        </row>
4564
4565        <row>
4566        <entry> <literal>\m</> </entry>
4567        <entry> matches only at the beginning of a word </entry>
4568        </row>
4569
4570        <row>
4571        <entry> <literal>\M</> </entry>
4572        <entry> matches only at the end of a word </entry>
4573        </row>
4574
4575        <row>
4576        <entry> <literal>\y</> </entry>
4577        <entry> matches only at the beginning or end of a word </entry>
4578        </row>
4579
4580        <row>
4581        <entry> <literal>\Y</> </entry>
4582        <entry> matches only at a point that is not the beginning or end of a
4583        word </entry>
4584        </row>
4585
4586        <row>
4587        <entry> <literal>\Z</> </entry>
4588        <entry> matches only at the end of the string
4589        (see <xref linkend="posix-matching-rules"> for how this differs from
4590        <literal>$</>) </entry>
4591        </row>
4592       </tbody>
4593      </tgroup>
4594     </table>
4595
4596    <para>
4597     A word is defined as in the specification of
4598     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4599     Constraint escapes are illegal within bracket expressions.
4600    </para>
4601
4602    <table id="posix-constraint-backref-table">
4603     <title>Regular Expression Back References</title>
4604
4605     <tgroup cols="2">
4606      <thead>
4607       <row>
4608        <entry>Escape</entry>
4609        <entry>Description</entry>
4610       </row>
4611      </thead>
4612
4613       <tbody>
4614        <row>
4615        <entry> <literal>\</><replaceable>m</> </entry>
4616        <entry> (where <replaceable>m</> is a nonzero digit)
4617        a back reference to the <replaceable>m</>'th subexpression </entry>
4618        </row>
4619
4620        <row>
4621        <entry> <literal>\</><replaceable>mnn</> </entry>
4622        <entry> (where <replaceable>m</> is a nonzero digit, and
4623        <replaceable>nn</> is some more digits, and the decimal value
4624        <replaceable>mnn</> is not greater than the number of closing capturing
4625        parentheses seen so far)
4626        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4627        </row>
4628       </tbody>
4629      </tgroup>
4630     </table>
4631
4632    <note>
4633     <para>
4634      There is an inherent ambiguity between octal character-entry
4635      escapes and back references, which is resolved by the following heuristics,
4636      as hinted at above.
4637      A leading zero always indicates an octal escape.
4638      A single non-zero digit, not followed by another digit,
4639      is always taken as a back reference.
4640      A multi-digit sequence not starting with a zero is taken as a back
4641      reference if it comes after a suitable subexpression
4642      (i.e., the number is in the legal range for a back reference),
4643      and otherwise is taken as octal.
4644     </para>
4645    </note>
4646    </sect3>
4647
4648    <sect3 id="posix-metasyntax">
4649     <title>Regular Expression Metasyntax</title>
4650
4651    <para>
4652     In addition to the main syntax described above, there are some special
4653     forms and miscellaneous syntactic facilities available.
4654    </para>
4655
4656    <para>
4657     An RE can begin with one of two special <firstterm>director</> prefixes.
4658     If an RE begins with <literal>***:</>,
4659     the rest of the RE is taken as an ARE.  (This normally has no effect in
4660     <productname>PostgreSQL</>, since REs are assumed to be AREs;
4661     but it does have an effect if ERE or BRE mode had been specified by
4662     the <replaceable>flags</> parameter to a regex function.)
4663     If an RE begins with <literal>***=</>,
4664     the rest of the RE is taken to be a literal string,
4665     with all characters considered ordinary characters.
4666    </para>
4667
4668    <para>
4669     An ARE can begin with <firstterm>embedded options</>:
4670     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4671     (where <replaceable>xyz</> is one or more alphabetic characters)
4672     specifies options affecting the rest of the RE.
4673     These options override any previously determined options &mdash;
4674     in particular, they can override the case-sensitivity behavior implied by
4675     a regex operator, or the <replaceable>flags</> parameter to a regex
4676     function.
4677     The available option letters are
4678     shown in <xref linkend="posix-embedded-options-table">.
4679     Note that these same option letters are used in the <replaceable>flags</>
4680     parameters of regex functions.
4681    </para>
4682
4683    <table id="posix-embedded-options-table">
4684     <title>ARE Embedded-option Letters</title>
4685
4686     <tgroup cols="2">
4687      <thead>
4688       <row>
4689        <entry>Option</entry>
4690        <entry>Description</entry>
4691       </row>
4692      </thead>
4693
4694       <tbody>
4695        <row>
4696        <entry> <literal>b</> </entry>
4697        <entry> rest of RE is a BRE </entry>
4698        </row>
4699
4700        <row>
4701        <entry> <literal>c</> </entry>
4702        <entry> case-sensitive matching (overrides operator type) </entry>
4703        </row>
4704
4705        <row>
4706        <entry> <literal>e</> </entry>
4707        <entry> rest of RE is an ERE </entry>
4708        </row>
4709
4710        <row>
4711        <entry> <literal>i</> </entry>
4712        <entry> case-insensitive matching (see
4713        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4714        </row>
4715
4716        <row>
4717        <entry> <literal>m</> </entry>
4718        <entry> historical synonym for <literal>n</> </entry>
4719        </row>
4720
4721        <row>
4722        <entry> <literal>n</> </entry>
4723        <entry> newline-sensitive matching (see
4724        <xref linkend="posix-matching-rules">) </entry>
4725        </row>
4726
4727        <row>
4728        <entry> <literal>p</> </entry>
4729        <entry> partial newline-sensitive matching (see
4730        <xref linkend="posix-matching-rules">) </entry>
4731        </row>
4732
4733        <row>
4734        <entry> <literal>q</> </entry>
4735        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4736        characters </entry>
4737        </row>
4738
4739        <row>
4740        <entry> <literal>s</> </entry>
4741        <entry> non-newline-sensitive matching (default) </entry>
4742        </row>
4743
4744        <row>
4745        <entry> <literal>t</> </entry>
4746        <entry> tight syntax (default; see below) </entry>
4747        </row>
4748
4749        <row>
4750        <entry> <literal>w</> </entry>
4751        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4752        (see <xref linkend="posix-matching-rules">) </entry>
4753        </row>
4754
4755        <row>
4756        <entry> <literal>x</> </entry>
4757        <entry> expanded syntax (see below) </entry>
4758        </row>
4759       </tbody>
4760      </tgroup>
4761     </table>
4762
4763    <para>
4764     Embedded options take effect at the <literal>)</> terminating the sequence.
4765     They can appear only at the start of an ARE (after the
4766     <literal>***:</> director if any).
4767    </para>
4768
4769    <para>
4770     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4771     characters are significant, there is an <firstterm>expanded</> syntax,
4772     available by specifying the embedded <literal>x</> option.
4773     In the expanded syntax,
4774     white-space characters in the RE are ignored, as are
4775     all characters between a <literal>#</>
4776     and the following newline (or the end of the RE).  This
4777     permits paragraphing and commenting a complex RE.
4778     There are three exceptions to that basic rule:
4779
4780     <itemizedlist>
4781      <listitem>
4782       <para>
4783        a white-space character or <literal>#</> preceded by <literal>\</> is
4784        retained
4785       </para>
4786      </listitem>
4787      <listitem>
4788       <para>
4789        white space or <literal>#</> within a bracket expression is retained
4790       </para>
4791      </listitem>
4792      <listitem>
4793       <para>
4794        white space and comments cannot appear within multi-character symbols,
4795        such as <literal>(?:</>
4796       </para>
4797      </listitem>
4798     </itemizedlist>
4799
4800     For this purpose, white-space characters are blank, tab, newline, and
4801     any character that belongs to the <replaceable>space</> character class.
4802    </para>
4803
4804    <para>
4805     Finally, in an ARE, outside bracket expressions, the sequence
4806     <literal>(?#</><replaceable>ttt</><literal>)</>
4807     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4808     is a comment, completely ignored.
4809     Again, this is not allowed between the characters of
4810     multi-character symbols, like <literal>(?:</>.
4811     Such comments are more a historical artifact than a useful facility,
4812     and their use is deprecated; use the expanded syntax instead.
4813    </para>
4814
4815    <para>
4816     <emphasis>None</> of these metasyntax extensions is available if
4817     an initial <literal>***=</> director
4818     has specified that the user's input be treated as a literal string
4819     rather than as an RE.
4820    </para>
4821    </sect3>
4822
4823    <sect3 id="posix-matching-rules">
4824     <title>Regular Expression Matching Rules</title>
4825
4826    <para>
4827     In the event that an RE could match more than one substring of a given
4828     string, the RE matches the one starting earliest in the string.
4829     If the RE could match more than one substring starting at that point,
4830     either the longest possible match or the shortest possible match will
4831     be taken, depending on whether the RE is <firstterm>greedy</> or
4832     <firstterm>non-greedy</>.
4833    </para>
4834
4835    <para>
4836     Whether an RE is greedy or not is determined by the following rules:
4837     <itemizedlist>
4838      <listitem>
4839       <para>
4840        Most atoms, and all constraints, have no greediness attribute (because
4841        they cannot match variable amounts of text anyway).
4842       </para>
4843      </listitem>
4844      <listitem>
4845       <para>
4846        Adding parentheses around an RE does not change its greediness.
4847       </para>
4848      </listitem>
4849      <listitem>
4850       <para>
4851        A quantified atom with a fixed-repetition quantifier
4852        (<literal>{</><replaceable>m</><literal>}</>
4853        or
4854        <literal>{</><replaceable>m</><literal>}?</>)
4855        has the same greediness (possibly none) as the atom itself.
4856       </para>
4857      </listitem>
4858      <listitem>
4859       <para>
4860        A quantified atom with other normal quantifiers (including
4861        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4862        with <replaceable>m</> equal to <replaceable>n</>)
4863        is greedy (prefers longest match).
4864       </para>
4865      </listitem>
4866      <listitem>
4867       <para>
4868        A quantified atom with a non-greedy quantifier (including
4869        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4870        with <replaceable>m</> equal to <replaceable>n</>)
4871        is non-greedy (prefers shortest match).
4872       </para>
4873      </listitem>
4874      <listitem>
4875       <para>
4876        A branch &mdash; that is, an RE that has no top-level
4877        <literal>|</> operator &mdash; has the same greediness as the first
4878        quantified atom in it that has a greediness attribute.
4879       </para>
4880      </listitem>
4881      <listitem>
4882       <para>
4883        An RE consisting of two or more branches connected by the
4884        <literal>|</> operator is always greedy.
4885       </para>
4886      </listitem>
4887     </itemizedlist>
4888    </para>
4889
4890    <para>
4891     The above rules associate greediness attributes not only with individual
4892     quantified atoms, but with branches and entire REs that contain quantified
4893     atoms.  What that means is that the matching is done in such a way that
4894     the branch, or whole RE, matches the longest or shortest possible
4895     substring <emphasis>as a whole</>.  Once the length of the entire match
4896     is determined, the part of it that matches any particular subexpression
4897     is determined on the basis of the greediness attribute of that
4898     subexpression, with subexpressions starting earlier in the RE taking
4899     priority over ones starting later.
4900    </para>
4901
4902    <para>
4903     An example of what this means:
4904 <screen>
4905 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4906 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4907 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4908 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4909 </screen>
4910     In the first case, the RE as a whole is greedy because <literal>Y*</>
4911     is greedy.  It can match beginning at the <literal>Y</>, and it matches
4912     the longest possible string starting there, i.e., <literal>Y123</>.
4913     The output is the parenthesized part of that, or <literal>123</>.
4914     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4915     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
4916     the shortest possible string starting there, i.e., <literal>Y1</>.
4917     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4918     the decision as to the overall match length; so it is forced to match
4919     just <literal>1</>.
4920    </para>
4921
4922    <para>
4923     In short, when an RE contains both greedy and non-greedy subexpressions,
4924     the total match length is either as long as possible or as short as
4925     possible, according to the attribute assigned to the whole RE.  The
4926     attributes assigned to the subexpressions only affect how much of that
4927     match they are allowed to <quote>eat</> relative to each other.
4928    </para>
4929
4930    <para>
4931     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4932     can be used to force greediness or non-greediness, respectively,
4933     on a subexpression or a whole RE.
4934    </para>
4935
4936    <para>
4937     Match lengths are measured in characters, not collating elements.
4938     An empty string is considered longer than no match at all.
4939     For example:
4940     <literal>bb*</>
4941     matches the three middle characters of <literal>abbbc</>;
4942     <literal>(week|wee)(night|knights)</>
4943     matches all ten characters of <literal>weeknights</>;
4944     when <literal>(.*).*</>
4945     is matched against <literal>abc</> the parenthesized subexpression
4946     matches all three characters; and when
4947     <literal>(a*)*</> is matched against <literal>bc</>
4948     both the whole RE and the parenthesized
4949     subexpression match an empty string.
4950    </para>
4951
4952    <para>
4953     If case-independent matching is specified,
4954     the effect is much as if all case distinctions had vanished from the
4955     alphabet.
4956     When an alphabetic that exists in multiple cases appears as an
4957     ordinary character outside a bracket expression, it is effectively
4958     transformed into a bracket expression containing both cases,
4959     e.g., <literal>x</> becomes <literal>[xX]</>.
4960     When it appears inside a bracket expression, all case counterparts
4961     of it are added to the bracket expression, e.g.,
4962     <literal>[x]</> becomes <literal>[xX]</>
4963     and <literal>[^x]</> becomes <literal>[^xX]</>.
4964    </para>
4965
4966    <para>
4967     If newline-sensitive matching is specified, <literal>.</>
4968     and bracket expressions using <literal>^</>
4969     will never match the newline character
4970     (so that matches will never cross newlines unless the RE
4971     explicitly arranges it)
4972     and <literal>^</>and <literal>$</>
4973     will match the empty string after and before a newline
4974     respectively, in addition to matching at beginning and end of string
4975     respectively.
4976     But the ARE escapes <literal>\A</> and <literal>\Z</>
4977     continue to match beginning or end of string <emphasis>only</>.
4978    </para>
4979
4980    <para>
4981     If partial newline-sensitive matching is specified,
4982     this affects <literal>.</> and bracket expressions
4983     as with newline-sensitive matching, but not <literal>^</>
4984     and <literal>$</>.
4985    </para>
4986
4987    <para>
4988     If inverse partial newline-sensitive matching is specified,
4989     this affects <literal>^</> and <literal>$</>
4990     as with newline-sensitive matching, but not <literal>.</>
4991     and bracket expressions.
4992     This isn't very useful but is provided for symmetry.
4993    </para>
4994    </sect3>
4995
4996    <sect3 id="posix-limits-compatibility">
4997     <title>Limits and Compatibility</title>
4998
4999    <para>
5000     No particular limit is imposed on the length of REs in this
5001     implementation.  However,
5002     programs intended to be highly portable should not employ REs longer
5003     than 256 bytes,
5004     as a POSIX-compliant implementation can refuse to accept such REs.
5005    </para>
5006
5007    <para>
5008     The only feature of AREs that is actually incompatible with
5009     POSIX EREs is that <literal>\</> does not lose its special
5010     significance inside bracket expressions.
5011     All other ARE features use syntax which is illegal or has
5012     undefined or unspecified effects in POSIX EREs;
5013     the <literal>***</> syntax of directors likewise is outside the POSIX
5014     syntax for both BREs and EREs.
5015    </para>
5016
5017    <para>
5018     Many of the ARE extensions are borrowed from Perl, but some have
5019     been changed to clean them up, and a few Perl extensions are not present.
5020     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
5021     the lack of special treatment for a trailing newline,
5022     the addition of complemented bracket expressions to the things
5023     affected by newline-sensitive matching,
5024     the restrictions on parentheses and back references in lookahead
5025     constraints, and the longest/shortest-match (rather than first-match)
5026     matching semantics.
5027    </para>
5028
5029    <para>
5030     Two significant incompatibilities exist between AREs and the ERE syntax
5031     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
5032
5033     <itemizedlist>
5034      <listitem>
5035       <para>
5036        In AREs, <literal>\</> followed by an alphanumeric character is either
5037        an escape or an error, while in previous releases, it was just another
5038        way of writing the alphanumeric.
5039        This should not be much of a problem because there was no reason to
5040        write such a sequence in earlier releases.
5041       </para>
5042      </listitem>
5043      <listitem>
5044       <para>
5045        In AREs, <literal>\</> remains a special character within
5046        <literal>[]</>, so a literal <literal>\</> within a bracket
5047        expression must be written <literal>\\</>.
5048       </para>
5049      </listitem>
5050     </itemizedlist>
5051    </para>
5052    </sect3>
5053
5054    <sect3 id="posix-basic-regexes">
5055     <title>Basic Regular Expressions</title>
5056
5057    <para>
5058     BREs differ from EREs in several respects.
5059     In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
5060     are ordinary characters and there is no equivalent
5061     for their functionality.
5062     The delimiters for bounds are
5063     <literal>\{</> and <literal>\}</>,
5064     with <literal>{</> and <literal>}</>
5065     by themselves ordinary characters.
5066     The parentheses for nested subexpressions are
5067     <literal>\(</> and <literal>\)</>,
5068     with <literal>(</> and <literal>)</> by themselves ordinary characters.
5069     <literal>^</> is an ordinary character except at the beginning of the
5070     RE or the beginning of a parenthesized subexpression,
5071     <literal>$</> is an ordinary character except at the end of the
5072     RE or the end of a parenthesized subexpression,
5073     and <literal>*</> is an ordinary character if it appears at the beginning
5074     of the RE or the beginning of a parenthesized subexpression
5075     (after a possible leading <literal>^</>).
5076     Finally, single-digit back references are available, and
5077     <literal>\&lt;</> and <literal>\&gt;</>
5078     are synonyms for
5079     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
5080     respectively; no other escapes are available in BREs.
5081    </para>
5082    </sect3>
5083
5084 <!-- end re_syntax.n man page -->
5085
5086   </sect2>
5087  </sect1>
5088
5089
5090   <sect1 id="functions-formatting">
5091    <title>Data Type Formatting Functions</title>
5092
5093    <indexterm>
5094     <primary>formatting</primary>
5095    </indexterm>
5096
5097    <para>
5098     The <productname>PostgreSQL</productname> formatting functions
5099     provide a powerful set of tools for converting various data types
5100     (date/time, integer, floating point, numeric) to formatted strings
5101     and for converting from formatted strings to specific data types.
5102     <xref linkend="functions-formatting-table"> lists them.
5103     These functions all follow a common calling convention: the first
5104     argument is the value to be formatted and the second argument is a
5105     template that defines the output or input format.
5106    </para>
5107    <para>
5108     A single-argument <function>to_timestamp</function> function is also
5109     available;  it accepts a
5110     <type>double precision</type> argument and converts from Unix epoch
5111     (seconds since 1970-01-01 00:00:00+00) to
5112     <type>timestamp with time zone</type>.
5113     (<type>Integer</type> Unix epochs are implicitly cast to
5114     <type>double precision</type>.)
5115    </para>
5116
5117     <table id="functions-formatting-table">
5118      <title>Formatting Functions</title>
5119      <tgroup cols="4">
5120       <thead>
5121        <row>
5122         <entry>Function</entry>
5123         <entry>Return Type</entry>
5124         <entry>Description</entry>
5125         <entry>Example</entry>
5126        </row>
5127       </thead>
5128       <tbody>
5129        <row>
5130         <entry>
5131          <indexterm>
5132           <primary>to_char</primary>
5133          </indexterm>
5134          <literal><function>to_char(<type>timestamp</type>, <type>text</type>)</function></literal>
5135         </entry>
5136         <entry><type>text</type></entry>
5137         <entry>convert time stamp to string</entry>
5138         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
5139        </row>
5140        <row>
5141         <entry><literal><function>to_char(<type>interval</type>, <type>text</type>)</function></literal></entry>
5142         <entry><type>text</type></entry>
5143         <entry>convert interval to string</entry>
5144         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
5145        </row>
5146        <row>
5147         <entry><literal><function>to_char(<type>int</type>, <type>text</type>)</function></literal></entry>
5148         <entry><type>text</type></entry>
5149         <entry>convert integer to string</entry>
5150         <entry><literal>to_char(125, '999')</literal></entry>
5151        </row>
5152        <row>
5153         <entry><literal><function>to_char</function>(<type>double precision</type>,
5154         <type>text</type>)</literal></entry>
5155         <entry><type>text</type></entry>
5156         <entry>convert real/double precision to string</entry>
5157         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
5158        </row>
5159        <row>
5160         <entry><literal><function>to_char(<type>numeric</type>, <type>text</type>)</function></literal></entry>
5161         <entry><type>text</type></entry>
5162         <entry>convert numeric to string</entry>
5163         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
5164        </row>
5165        <row>
5166         <entry>
5167          <indexterm>
5168           <primary>to_date</primary>
5169          </indexterm>
5170          <literal><function>to_date(<type>text</type>, <type>text</type>)</function></literal>
5171         </entry>
5172         <entry><type>date</type></entry>
5173         <entry>convert string to date</entry>
5174         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5175        </row>
5176        <row>
5177         <entry>
5178          <indexterm>
5179           <primary>to_number</primary>
5180          </indexterm>
5181          <literal><function>to_number(<type>text</type>, <type>text</type>)</function></literal>
5182         </entry>
5183         <entry><type>numeric</type></entry>
5184         <entry>convert string to numeric</entry>
5185         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
5186        </row>
5187        <row>
5188         <entry>
5189          <indexterm>
5190           <primary>to_timestamp</primary>
5191          </indexterm>
5192          <literal><function>to_timestamp(<type>text</type>, <type>text</type>)</function></literal>
5193         </entry>
5194         <entry><type>timestamp with time zone</type></entry>
5195         <entry>convert string to time stamp</entry>
5196         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5197        </row>
5198        <row>
5199         <entry><literal><function>to_timestamp(<type>double precision</type>)</function></literal></entry>
5200         <entry><type>timestamp with time zone</type></entry>
5201         <entry>convert Unix epoch to time stamp</entry>
5202         <entry><literal>to_timestamp(1284352323)</literal></entry>
5203        </row>
5204       </tbody>
5205      </tgroup>
5206     </table>
5207
5208    <para>
5209     In a <function>to_char</> output template string, there are certain
5210     patterns that are recognized and replaced with appropriately-formatted
5211     data based on the given value.  Any text that is not a template pattern is
5212     simply copied verbatim.  Similarly, in an input template string (for the
5213     other functions), template patterns identify the values to be supplied by
5214     the input data string.
5215    </para>
5216
5217   <para>
5218    <xref linkend="functions-formatting-datetime-table"> shows the
5219    template patterns available for formatting date and time values.
5220   </para>
5221
5222     <table id="functions-formatting-datetime-table">
5223      <title>Template Patterns for Date/Time Formatting</title>
5224      <tgroup cols="2">
5225       <thead>
5226        <row>
5227         <entry>Pattern</entry>
5228         <entry>Description</entry>
5229        </row>
5230       </thead>
5231       <tbody>
5232        <row>
5233         <entry><literal>HH</literal></entry>
5234         <entry>hour of day (01-12)</entry>
5235        </row>
5236        <row>
5237         <entry><literal>HH12</literal></entry>
5238         <entry>hour of day (01-12)</entry>
5239        </row>
5240        <row>
5241         <entry><literal>HH24</literal></entry>
5242         <entry>hour of day (00-23)</entry>
5243        </row>
5244        <row>
5245         <entry><literal>MI</literal></entry>
5246         <entry>minute (00-59)</entry>
5247        </row>
5248        <row>
5249         <entry><literal>SS</literal></entry>
5250         <entry>second (00-59)</entry>
5251        </row>
5252        <row>
5253         <entry><literal>MS</literal></entry>
5254         <entry>millisecond (000-999)</entry>
5255        </row>
5256        <row>
5257         <entry><literal>US</literal></entry>
5258         <entry>microsecond (000000-999999)</entry>
5259        </row>
5260        <row>
5261         <entry><literal>SSSS</literal></entry>
5262         <entry>seconds past midnight (0-86399)</entry>
5263        </row>
5264        <row>
5265         <entry><literal>AM</literal>, <literal>am</literal>,
5266         <literal>PM</literal> or <literal>pm</literal></entry>
5267         <entry>meridiem indicator (without periods)</entry>
5268        </row>
5269        <row>
5270         <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
5271         <literal>P.M.</literal> or <literal>p.m.</literal></entry>
5272         <entry>meridiem indicator (with periods)</entry>
5273        </row>
5274        <row>
5275         <entry><literal>Y,YYY</literal></entry>
5276         <entry>year (4 and more digits) with comma</entry>
5277        </row>
5278        <row>
5279         <entry><literal>YYYY</literal></entry>
5280         <entry>year (4 and more digits)</entry>
5281        </row>
5282        <row>
5283         <entry><literal>YYY</literal></entry>
5284         <entry>last 3 digits of year</entry>
5285        </row>
5286        <row>
5287         <entry><literal>YY</literal></entry>
5288         <entry>last 2 digits of year</entry>
5289        </row>
5290        <row>
5291         <entry><literal>Y</literal></entry>
5292         <entry>last digit of year</entry>
5293        </row>
5294        <row>
5295         <entry><literal>IYYY</literal></entry>
5296         <entry>ISO year (4 and more digits)</entry>
5297        </row>
5298        <row>
5299         <entry><literal>IYY</literal></entry>
5300         <entry>last 3 digits of ISO year</entry>
5301        </row>
5302        <row>
5303         <entry><literal>IY</literal></entry>
5304         <entry>last 2 digits of ISO year</entry>
5305        </row>
5306        <row>
5307         <entry><literal>I</literal></entry>
5308         <entry>last digit of ISO year</entry>
5309        </row>
5310        <row>
5311         <entry><literal>BC</literal>, <literal>bc</literal>,
5312         <literal>AD</literal> or <literal>ad</literal></entry>
5313         <entry>era indicator (without periods)</entry>
5314        </row>
5315        <row>
5316         <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
5317         <literal>A.D.</literal> or <literal>a.d.</literal></entry>
5318         <entry>era indicator (with periods)</entry>
5319        </row>
5320        <row>
5321         <entry><literal>MONTH</literal></entry>
5322         <entry>full upper case month name (blank-padded to 9 chars)</entry>
5323        </row>
5324        <row>
5325         <entry><literal>Month</literal></entry>
5326         <entry>full capitalized month name (blank-padded to 9 chars)</entry>
5327        </row>
5328        <row>
5329         <entry><literal>month</literal></entry>
5330         <entry>full lower case month name (blank-padded to 9 chars)</entry>
5331        </row>
5332        <row>
5333         <entry><literal>MON</literal></entry>
5334         <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
5335        </row>
5336        <row>
5337         <entry><literal>Mon</literal></entry>
5338         <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
5339        </row>
5340        <row>
5341         <entry><literal>mon</literal></entry>
5342         <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
5343        </row>
5344        <row>
5345         <entry><literal>MM</literal></entry>
5346         <entry>month number (01-12)</entry>
5347        </row>
5348        <row>
5349         <entry><literal>DAY</literal></entry>
5350         <entry>full upper case day name (blank-padded to 9 chars)</entry>
5351        </row>
5352        <row>
5353         <entry><literal>Day</literal></entry>
5354         <entry>full capitalized day name (blank-padded to 9 chars)</entry>
5355        </row>
5356        <row>
5357         <entry><literal>day</literal></entry>
5358         <entry>full lower case day name (blank-padded to 9 chars)</entry>
5359        </row>
5360        <row>
5361         <entry><literal>DY</literal></entry>
5362         <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
5363        </row>
5364        <row>
5365         <entry><literal>Dy</literal></entry>
5366         <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
5367        </row>
5368        <row>
5369         <entry><literal>dy</literal></entry>
5370         <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
5371        </row>
5372        <row>
5373         <entry><literal>DDD</literal></entry>
5374         <entry>day of year (001-366)</entry>
5375        </row>
5376        <row>
5377         <entry><literal>IDDD</literal></entry>
5378         <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
5379        </row>
5380        <row>
5381         <entry><literal>DD</literal></entry>
5382         <entry>day of month (01-31)</entry>
5383        </row>
5384        <row>
5385         <entry><literal>D</literal></entry>
5386         <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
5387        </row>
5388        <row>
5389         <entry><literal>ID</literal></entry>
5390         <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
5391        </row>
5392        <row>
5393         <entry><literal>W</literal></entry>
5394         <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
5395        </row>
5396        <row>
5397         <entry><literal>WW</literal></entry>
5398         <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
5399        </row>
5400        <row>
5401         <entry><literal>IW</literal></entry>
5402         <entry>ISO week number of year (01 - 53; the first Thursday of the new year is in week 1.)</entry>
5403        </row>
5404        <row>
5405         <entry><literal>CC</literal></entry>
5406         <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
5407        </row>
5408        <row>
5409         <entry><literal>J</literal></entry>
5410         <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
5411        </row>
5412        <row>
5413         <entry><literal>Q</literal></entry>
5414         <entry>quarter (ignored by <function>to_date</> and <function>to_timestamp</>)</entry>
5415        </row>
5416        <row>
5417         <entry><literal>RM</literal></entry>
5418         <entry>month in upper case Roman numerals (I-XII; I=January)</entry>
5419        </row>
5420        <row>
5421         <entry><literal>rm</literal></entry>
5422         <entry>month in lower case Roman numerals (i-xii; i=January)</entry>
5423        </row>
5424        <row>
5425         <entry><literal>TZ</literal></entry>
5426         <entry>upper case time-zone name</entry>
5427        </row>
5428        <row>
5429         <entry><literal>tz</literal></entry>
5430         <entry>lower case time-zone name</entry>
5431        </row>
5432       </tbody>
5433      </tgroup>
5434     </table>
5435
5436    <para>
5437     Modifiers can be applied to any template pattern to alter its
5438     behavior.  For example, <literal>FMMonth</literal>
5439     is the <literal>Month</literal> pattern with the
5440     <literal>FM</literal> modifier.
5441     <xref linkend="functions-formatting-datetimemod-table"> shows the
5442     modifier patterns for date/time formatting.
5443    </para>
5444
5445     <table id="functions-formatting-datetimemod-table">
5446      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5447      <tgroup cols="3">
5448       <thead>
5449        <row>
5450         <entry>Modifier</entry>
5451         <entry>Description</entry>
5452         <entry>Example</entry>
5453        </row>
5454       </thead>
5455       <tbody>
5456        <row>
5457         <entry><literal>FM</literal> prefix</entry>
5458         <entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
5459         <entry><literal>FMMonth</literal></entry>
5460        </row>
5461        <row>
5462         <entry><literal>TH</literal> suffix</entry>
5463         <entry>upper case ordinal number suffix</entry>
5464         <entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
5465        </row>
5466        <row>
5467         <entry><literal>th</literal> suffix</entry>
5468         <entry>lower case ordinal number suffix</entry>
5469         <entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
5470        </row>
5471        <row>
5472         <entry><literal>FX</literal> prefix</entry>
5473         <entry>fixed format global option (see usage notes)</entry>
5474         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5475        </row>
5476        <row>
5477         <entry><literal>TM</literal> prefix</entry>
5478         <entry>translation mode (print localized day and month names based on
5479          <xref linkend="guc-lc-time">)</entry>
5480         <entry><literal>TMMonth</literal></entry>
5481        </row>
5482        <row>
5483         <entry><literal>SP</literal> suffix</entry>
5484         <entry>spell mode (not implemented)</entry>
5485         <entry><literal>DDSP</literal></entry>
5486        </row>
5487       </tbody>
5488      </tgroup>
5489     </table>
5490
5491    <para>
5492     Usage notes for date/time formatting:
5493
5494     <itemizedlist>
5495      <listitem>
5496       <para>
5497        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5498        that would otherwise be added to make the output of a pattern be
5499        fixed-width.  In <productname>PostgreSQL</productname>,
5500        <literal>FM</literal> modifies only the next specification, while in
5501        Oracle <literal>FM</literal> affects all subsequent
5502        specifications, and repeated <literal>FM</literal> modifiers
5503        toggle fill mode on and off.
5504       </para>
5505      </listitem>
5506
5507      <listitem>
5508       <para>
5509        <literal>TM</literal> does not include trailing blanks.
5510       </para>
5511      </listitem>
5512
5513      <listitem>
5514       <para>
5515        <function>to_timestamp</function> and <function>to_date</function>
5516        skip multiple blank spaces in the input string unless the
5517        <literal>FX</literal> option is used. For example,
5518        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> works, but
5519        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
5520        because <function>to_timestamp</function> expects one space only.
5521        <literal>FX</literal> must be specified as the first item in
5522        the template.
5523       </para>
5524      </listitem>
5525
5526      <listitem>
5527       <para>
5528        Ordinary text is allowed in <function>to_char</function>
5529        templates and will be output literally.  You can put a substring
5530        in double quotes to force it to be interpreted as literal text
5531        even if it contains pattern key words.  For example, in
5532        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5533        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5534        will not be.  In <function>to_date</>, <function>to_number</>,
5535        and <function>to_timestamp</>, double-quoted strings skip the number of
5536        input characters contained in the string, e.g. <literal>"XX"</>
5537        skips two input characters.
5538       </para>
5539      </listitem>
5540
5541      <listitem>
5542       <para>
5543        If you want to have a double quote in the output you must
5544        precede it with a backslash, for example <literal>E'\\"YYYY
5545        Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
5546        (Two backslashes are necessary because the backslash
5547        has special meaning when using the escape string syntax.)
5548       </para>
5549      </listitem>
5550
5551      <listitem>
5552       <para>
5553        If the year format specification is less than four digits, e.g.
5554        <literal>YYY</>, and the supplied year is less than four digits,
5555        the year will be adjusted to be nearest to the year 2020, e.g.
5556        <literal>95</> becomes 1995.
5557       </para>
5558      </listitem>
5559
5560      <listitem>
5561       <para>
5562        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5563        <type>date</type> has a restriction when processing years with more than 4 digits. You must
5564        use some non-digit character or template after <literal>YYYY</literal>,
5565        otherwise the year is always interpreted as 4 digits. For example
5566        (with the year 20000):
5567        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
5568        interpreted as a 4-digit year; instead use a non-digit
5569        separator after the year, like
5570        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5571        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5572       </para>
5573      </listitem>
5574
5575      <listitem>
5576       <para>
5577        In conversions from string to <type>timestamp</type> or
5578        <type>date</type>, the <literal>CC</literal> (century) field is ignored
5579        if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
5580        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5581        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5582        as <literal>(CC-1)*100+YY</literal>.
5583       </para>
5584      </listitem>
5585
5586      <listitem>
5587       <para>
5588        An ISO week date (as distinct from a Gregorian date) can be
5589        specified to <function>to_timestamp</function> and
5590        <function>to_date</function> in one of two ways:
5591        <itemizedlist>
5592         <listitem>
5593          <para>
5594           Year, week, and weekday:  for example <literal>to_date('2006-42-4',
5595           'IYYY-IW-ID')</literal> returns the date
5596           <literal>2006-10-19</literal>.  If you omit the weekday it
5597           is assumed to be 1 (Monday).
5598          </para>
5599         </listitem>
5600         <listitem>
5601          <para>
5602           Year and day of year:  for example <literal>to_date('2006-291',
5603           'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5604          </para>
5605         </listitem>
5606        </itemizedlist>
5607       </para>
5608       <para>
5609        Attempting to construct a date using a mixture of ISO week and
5610        Gregorian date fields is nonsensical, and will cause an error.  In the
5611        context of an ISO year, the concept of a <quote>month</> or <quote>day
5612        of month</> has no meaning.  In the context of a Gregorian year, the
5613        ISO week has no meaning.  Users should avoid mixing Gregorian and
5614        ISO date specifications.
5615       </para>
5616      </listitem>
5617
5618      <listitem>
5619       <para>
5620        In a conversion from string to <type>timestamp</type>, millisecond
5621        (<literal>MS</literal>) or microsecond (<literal>US</literal>)
5622        values are used as the
5623        seconds digits after the decimal point. For example
5624        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5625        but 300, because the conversion counts it as 12 + 0.3 seconds.
5626        This means for the format <literal>SS:MS</literal>, the input values
5627        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5628        same number of milliseconds. To get three milliseconds, one must use
5629        <literal>12:003</literal>, which the conversion counts as
5630        12 + 0.003 = 12.003 seconds.
5631       </para>
5632
5633       <para>
5634        Here is a more
5635        complex example:
5636        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5637        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5638        1230 microseconds = 2.021230 seconds.
5639       </para>
5640      </listitem>
5641
5642      <listitem>
5643       <para>
5644         <function>to_char(..., 'ID')</function>'s day of the week numbering
5645         matches the <function>extract(isodow from ...)</function> function, but
5646         <function>to_char(..., 'D')</function>'s does not match
5647         <function>extract(dow from ...)</function>'s day numbering.
5648       </para>
5649      </listitem>
5650
5651      <listitem>
5652       <para>
5653         <function>to_char(interval)</function> formats <literal>HH</> and
5654         <literal>HH12</> as shown on a 12-hour clock, i.e. zero hours
5655         and 36 hours output as <literal>12</>, while <literal>HH24</>
5656         outputs the full hour value, which can exceed 23 for intervals.
5657       </para>
5658      </listitem>
5659
5660     </itemizedlist>
5661    </para>
5662
5663   <para>
5664    <xref linkend="functions-formatting-numeric-table"> shows the
5665    template patterns available for formatting numeric values.
5666   </para>
5667
5668     <table id="functions-formatting-numeric-table">
5669      <title>Template Patterns for Numeric Formatting</title>
5670      <tgroup cols="2">
5671       <thead>
5672        <row>
5673         <entry>Pattern</entry>
5674         <entry>Description</entry>
5675        </row>
5676       </thead>
5677       <tbody>
5678        <row>
5679         <entry><literal>9</literal></entry>
5680         <entry>value with the specified number of digits</entry>
5681        </row>
5682        <row>
5683         <entry><literal>0</literal></entry>
5684         <entry>value with leading zeros</entry>
5685        </row>
5686        <row>
5687         <entry><literal>.</literal> (period)</entry>
5688         <entry>decimal point</entry>
5689        </row>
5690        <row>
5691         <entry><literal>,</literal> (comma)</entry>
5692         <entry>group (thousand) separator</entry>
5693        </row>
5694        <row>
5695         <entry><literal>PR</literal></entry>
5696         <entry>negative value in angle brackets</entry>
5697        </row>
5698        <row>
5699         <entry><literal>S</literal></entry>
5700         <entry>sign anchored to number (uses locale)</entry>
5701        </row>
5702        <row>
5703         <entry><literal>L</literal></entry>
5704         <entry>currency symbol (uses locale)</entry>
5705        </row>
5706        <row>
5707         <entry><literal>D</literal></entry>
5708         <entry>decimal point (uses locale)</entry>
5709        </row>
5710        <row>
5711         <entry><literal>G</literal></entry>
5712         <entry>group separator (uses locale)</entry>
5713        </row>
5714        <row>
5715         <entry><literal>MI</literal></entry>
5716         <entry>minus sign in specified position (if number &lt; 0)</entry>
5717        </row>
5718        <row>
5719         <entry><literal>PL</literal></entry>
5720         <entry>plus sign in specified position (if number &gt; 0)</entry>
5721        </row>
5722        <row>
5723         <entry><literal>SG</literal></entry>
5724         <entry>plus/minus sign in specified position</entry>
5725        </row>
5726        <row>
5727         <entry><literal>RN</literal></entry>
5728         <entry>Roman numeral (input between 1 and 3999)</entry>
5729        </row>
5730        <row>
5731         <entry><literal>TH</literal> or <literal>th</literal></entry>
5732         <entry>ordinal number suffix</entry>
5733        </row>
5734        <row>
5735         <entry><literal>V</literal></entry>
5736         <entry>shift specified number of digits (see notes)</entry>
5737        </row>
5738        <row>
5739         <entry><literal>EEEE</literal></entry>
5740         <entry>exponent for scientific notation</entry>
5741        </row>
5742       </tbody>
5743      </tgroup>
5744     </table>
5745
5746    <para>
5747     Usage notes for numeric formatting:
5748
5749     <itemizedlist>
5750      <listitem>
5751       <para>
5752        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5753        <literal>MI</literal> is not anchored to
5754        the number; for example,
5755        <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
5756        but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
5757        The Oracle implementation does not allow the use of
5758        <literal>MI</literal> before <literal>9</literal>, but rather
5759        requires that <literal>9</literal> precede
5760        <literal>MI</literal>.
5761       </para>
5762      </listitem>
5763
5764      <listitem>
5765       <para>
5766        <literal>9</literal> results in a value with the same number of
5767        digits as there are <literal>9</literal>s. If a digit is
5768        not available it outputs a space.
5769       </para>
5770      </listitem>
5771
5772      <listitem>
5773       <para>
5774        <literal>TH</literal> does not convert values less than zero
5775        and does not convert fractional numbers.
5776       </para>
5777      </listitem>
5778
5779      <listitem>
5780       <para>
5781        <literal>PL</literal>, <literal>SG</literal>, and
5782        <literal>TH</literal> are <productname>PostgreSQL</productname>
5783        extensions.
5784       </para>
5785      </listitem>
5786
5787      <listitem>
5788       <para>
5789        <literal>V</literal> effectively
5790        multiplies the input values by
5791        <literal>10^<replaceable>n</replaceable></literal>, where
5792        <replaceable>n</replaceable> is the number of digits following
5793        <literal>V</literal>.
5794        <function>to_char</function> does not support the use of
5795        <literal>V</literal> combined with a decimal point
5796        (e.g., <literal>99.9V99</literal> is not allowed).
5797       </para>
5798      </listitem>
5799
5800      <listitem>
5801       <para>
5802        <literal>EEEE</literal> (scientific notation) cannot be used in
5803        combination with any of the other formatting patterns or
5804        modifiers other than digit and decimal point patterns, and must be at the end of the format string
5805        (e.g., <literal>9.99EEEE</literal> is a valid pattern).
5806       </para>
5807      </listitem>
5808     </itemizedlist>
5809    </para>
5810
5811    <para>
5812     Certain modifiers can be applied to any template pattern to alter its
5813     behavior.  For example, <literal>FM9999</literal>
5814     is the <literal>9999</literal> pattern with the
5815     <literal>FM</literal> modifier.
5816     <xref linkend="functions-formatting-numericmod-table"> shows the
5817     modifier patterns for numeric formatting.
5818    </para>
5819
5820     <table id="functions-formatting-numericmod-table">
5821      <title>Template Pattern Modifiers for Numeric Formatting</title>
5822      <tgroup cols="3">
5823       <thead>
5824        <row>
5825         <entry>Modifier</entry>
5826         <entry>Description</entry>
5827         <entry>Example</entry>
5828        </row>
5829       </thead>
5830       <tbody>
5831        <row>
5832         <entry><literal>FM</literal> prefix</entry>
5833         <entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
5834         <entry><literal>FM9999</literal></entry>
5835        </row>
5836        <row>
5837         <entry><literal>TH</literal> suffix</entry>
5838         <entry>upper case ordinal number suffix</entry>
5839         <entry><literal>999TH</literal></entry>
5840        </row>
5841        <row>
5842         <entry><literal>th</literal> suffix</entry>
5843         <entry>lower case ordinal number suffix</entry>
5844         <entry><literal>999th</literal></entry>
5845        </row>
5846       </tbody>
5847      </tgroup>
5848     </table>
5849
5850   <para>
5851    <xref linkend="functions-formatting-examples-table"> shows some
5852    examples of the use of the <function>to_char</function> function.
5853   </para>
5854
5855     <table id="functions-formatting-examples-table">
5856      <title><function>to_char</function> Examples</title>
5857      <tgroup cols="2">
5858       <thead>
5859        <row>
5860         <entry>Expression</entry>
5861         <entry>Result</entry>
5862        </row>
5863       </thead>
5864       <tbody>
5865        <row>
5866         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5867         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
5868        </row>
5869        <row>
5870         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5871         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
5872        </row>
5873        <row>
5874         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5875         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
5876        </row>
5877        <row>
5878         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5879         <entry><literal>'-.1'</literal></entry>
5880        </row>
5881        <row>
5882         <entry><literal>to_char(0.1, '0.9')</literal></entry>
5883         <entry><literal>'&nbsp;0.1'</literal></entry>
5884        </row>
5885        <row>
5886         <entry><literal>to_char(12, '9990999.9')</literal></entry>
5887         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
5888        </row>
5889        <row>
5890         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5891         <entry><literal>'0012.'</literal></entry>
5892        </row>
5893        <row>
5894         <entry><literal>to_char(485, '999')</literal></entry>
5895         <entry><literal>'&nbsp;485'</literal></entry>
5896        </row>
5897        <row>
5898         <entry><literal>to_char(-485, '999')</literal></entry>
5899         <entry><literal>'-485'</literal></entry>
5900        </row>
5901        <row>
5902         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
5903         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
5904        </row>
5905        <row>
5906         <entry><literal>to_char(1485, '9,999')</literal></entry>
5907         <entry><literal>'&nbsp;1,485'</literal></entry>
5908        </row>
5909        <row>
5910         <entry><literal>to_char(1485, '9G999')</literal></entry>
5911         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
5912        </row>
5913        <row>
5914         <entry><literal>to_char(148.5, '999.999')</literal></entry>
5915         <entry><literal>'&nbsp;148.500'</literal></entry>
5916        </row>
5917        <row>
5918         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5919         <entry><literal>'148.5'</literal></entry>
5920        </row>
5921        <row>
5922         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5923         <entry><literal>'148.500'</literal></entry>
5924        </row>
5925        <row>
5926         <entry><literal>to_char(148.5, '999D999')</literal></entry>
5927         <entry><literal>'&nbsp;148,500'</literal></entry>
5928        </row>
5929        <row>
5930         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5931         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
5932        </row>
5933        <row>
5934         <entry><literal>to_char(-485, '999S')</literal></entry>
5935         <entry><literal>'485-'</literal></entry>
5936        </row>
5937        <row>
5938         <entry><literal>to_char(-485, '999MI')</literal></entry>
5939         <entry><literal>'485-'</literal></entry>
5940        </row>
5941        <row>
5942         <entry><literal>to_char(485, '999MI')</literal></entry>
5943         <entry><literal>'485&nbsp;'</literal></entry>
5944        </row>
5945        <row>
5946         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5947         <entry><literal>'485'</literal></entry>
5948        </row>
5949        <row>
5950         <entry><literal>to_char(485, 'PL999')</literal></entry>
5951         <entry><literal>'+485'</literal></entry>
5952        </row>
5953        <row>
5954         <entry><literal>to_char(485, 'SG999')</literal></entry>
5955         <entry><literal>'+485'</literal></entry>
5956        </row>
5957        <row>
5958         <entry><literal>to_char(-485, 'SG999')</literal></entry>
5959         <entry><literal>'-485'</literal></entry>
5960        </row>
5961        <row>
5962         <entry><literal>to_char(-485, '9SG99')</literal></entry>
5963         <entry><literal>'4-85'</literal></entry>
5964        </row>
5965        <row>
5966         <entry><literal>to_char(-485, '999PR')</literal></entry>
5967         <entry><literal>'&lt;485&gt;'</literal></entry>
5968        </row>
5969        <row>
5970         <entry><literal>to_char(485, 'L999')</literal></entry>
5971         <entry><literal>'DM&nbsp;485</literal></entry>
5972        </row>
5973        <row>
5974         <entry><literal>to_char(485, 'RN')</literal></entry>
5975         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
5976        </row>
5977        <row>
5978         <entry><literal>to_char(485, 'FMRN')</literal></entry>
5979         <entry><literal>'CDLXXXV'</literal></entry>
5980        </row>
5981        <row>
5982         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5983         <entry><literal>'V'</literal></entry>
5984        </row>
5985        <row>
5986         <entry><literal>to_char(482, '999th')</literal></entry>
5987         <entry><literal>'&nbsp;482nd'</literal></entry>
5988        </row>
5989        <row>
5990         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
5991         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
5992        </row>
5993        <row>
5994         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
5995         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
5996        </row>
5997        <row>
5998         <entry><literal>to_char(12, '99V999')</literal></entry>
5999         <entry><literal>'&nbsp;12000'</literal></entry>
6000        </row>
6001        <row>
6002         <entry><literal>to_char(12.4, '99V999')</literal></entry>
6003         <entry><literal>'&nbsp;12400'</literal></entry>
6004        </row>
6005        <row>
6006         <entry><literal>to_char(12.45, '99V9')</literal></entry>
6007         <entry><literal>'&nbsp;125'</literal></entry>
6008        </row>
6009        <row>
6010         <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
6011         <entry><literal>' 4.86e-04'</literal></entry>
6012        </row>
6013       </tbody>
6014      </tgroup>
6015     </table>
6016
6017   </sect1>
6018
6019
6020   <sect1 id="functions-datetime">
6021    <title>Date/Time Functions and Operators</title>
6022
6023   <para>
6024    <xref linkend="functions-datetime-table"> shows the available
6025    functions for date/time value processing, with details appearing in
6026    the following subsections.  <xref
6027    linkend="operators-datetime-table"> illustrates the behaviors of
6028    the basic arithmetic operators (<literal>+</literal>,
6029    <literal>*</literal>, etc.).  For formatting functions, refer to
6030    <xref linkend="functions-formatting">.  You should be familiar with
6031    the background information on date/time data types from <xref
6032    linkend="datatype-datetime">.
6033   </para>
6034
6035   <para>
6036    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
6037    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
6038    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
6039    For brevity, these variants are not shown separately.  Also, the
6040    <literal>+</> and <literal>*</> operators come in commutative pairs (for
6041    example both date + integer and integer + date); we show only one of each
6042    such pair.
6043   </para>
6044
6045     <table id="operators-datetime-table">
6046      <title>Date/Time Operators</title>
6047
6048      <tgroup cols="3">
6049       <thead>
6050        <row>
6051         <entry>Operator</entry>
6052         <entry>Example</entry>
6053         <entry>Result</entry>
6054        </row>
6055       </thead>
6056
6057       <tbody>
6058        <row>
6059         <entry> <literal>+</literal> </entry>
6060         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
6061         <entry><literal>date '2001-10-05'</literal></entry>
6062        </row>
6063
6064        <row>
6065         <entry> <literal>+</literal> </entry>
6066         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
6067         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
6068        </row>
6069
6070        <row>
6071         <entry> <literal>+</literal> </entry>
6072         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
6073         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
6074        </row>
6075
6076        <row>
6077         <entry> <literal>+</literal> </entry>
6078         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
6079         <entry><literal>interval '1 day 01:00:00'</literal></entry>
6080        </row>
6081
6082        <row>
6083         <entry> <literal>+</literal> </entry>
6084         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
6085         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
6086        </row>
6087
6088        <row>
6089         <entry> <literal>+</literal> </entry>
6090         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
6091         <entry><literal>time '04:00:00'</literal></entry>
6092        </row>
6093
6094        <row>
6095         <entry> <literal>-</literal> </entry>
6096         <entry><literal>- interval '23 hours'</literal></entry>
6097         <entry><literal>interval '-23:00:00'</literal></entry>
6098        </row>
6099
6100        <row>
6101         <entry> <literal>-</literal> </entry>
6102         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
6103         <entry><literal>integer '3'</literal> (days)</entry>
6104        </row>
6105
6106        <row>
6107         <entry> <literal>-</literal> </entry>
6108         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
6109         <entry><literal>date '2001-09-24'</literal></entry>
6110        </row>
6111
6112        <row>
6113         <entry> <literal>-</literal> </entry>
6114         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
6115         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
6116        </row>
6117
6118        <row>
6119         <entry> <literal>-</literal> </entry>
6120         <entry><literal>time '05:00' - time '03:00'</literal></entry>
6121         <entry><literal>interval '02:00:00'</literal></entry>
6122        </row>
6123
6124        <row>
6125         <entry> <literal>-</literal> </entry>
6126         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
6127         <entry><literal>time '03:00:00'</literal></entry>
6128        </row>
6129
6130        <row>
6131         <entry> <literal>-</literal> </entry>
6132         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
6133         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
6134        </row>
6135
6136        <row>
6137         <entry> <literal>-</literal> </entry>
6138         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
6139         <entry><literal>interval '1 day -01:00:00'</literal></entry>
6140        </row>
6141
6142        <row>
6143         <entry> <literal>-</literal> </entry>
6144         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
6145         <entry><literal>interval '1 day 15:00:00'</literal></entry>
6146        </row>
6147
6148        <row>
6149         <entry> <literal>*</literal> </entry>
6150         <entry><literal>900 * interval '1 second'</literal></entry>
6151         <entry><literal>interval '00:15:00'</literal></entry>
6152        </row>
6153
6154        <row>
6155         <entry> <literal>*</literal> </entry>
6156         <entry><literal>21 * interval '1 day'</literal></entry>
6157         <entry><literal>interval '21 days'</literal></entry>
6158        </row>
6159
6160        <row>
6161         <entry> <literal>*</literal> </entry>
6162         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
6163         <entry><literal>interval '03:30:00'</literal></entry>
6164        </row>
6165
6166        <row>
6167         <entry> <literal>/</literal> </entry>
6168         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
6169         <entry><literal>interval '00:40:00'</literal></entry>
6170        </row>
6171       </tbody>
6172      </tgroup>
6173     </table>
6174
6175     <table id="functions-datetime-table">
6176      <title>Date/Time Functions</title>
6177      <tgroup cols="5">
6178       <thead>
6179        <row>
6180         <entry>Function</entry>
6181         <entry>Return Type</entry>
6182         <entry>Description</entry>
6183         <entry>Example</entry>
6184         <entry>Result</entry>
6185        </row>
6186       </thead>
6187
6188       <tbody>
6189        <row>
6190         <entry>
6191          <indexterm>
6192           <primary>age</primary>
6193          </indexterm>
6194          <literal><function>age(<type>timestamp</type>, <type>timestamp</type>)</function></literal>
6195         </entry>
6196         <entry><type>interval</type></entry>
6197         <entry>Subtract arguments, producing a <quote>symbolic</> result that
6198         uses years and months</entry>
6199         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
6200         <entry><literal>43 years 9 mons 27 days</literal></entry>
6201        </row>
6202
6203        <row>
6204         <entry><literal><function>age(<type>timestamp</type>)</function></literal></entry>
6205         <entry><type>interval</type></entry>
6206         <entry>Subtract from <function>current_date</function> (at midnight)</entry>
6207         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
6208         <entry><literal>43 years 8 mons 3 days</literal></entry>
6209        </row>
6210
6211        <row>
6212         <entry>
6213          <indexterm>
6214           <primary>clock_timestamp</primary>
6215          </indexterm>
6216          <literal><function>clock_timestamp()</function></literal>
6217         </entry>
6218         <entry><type>timestamp with time zone</type></entry>
6219         <entry>Current date and time (changes during statement execution);
6220          see <xref linkend="functions-datetime-current">
6221         </entry>
6222         <entry></entry>
6223         <entry></entry>
6224        </row>
6225
6226        <row>
6227         <entry>
6228          <indexterm>
6229           <primary>current_date</primary>
6230          </indexterm>
6231          <literal><function>current_date</function></literal>
6232         </entry>
6233         <entry><type>date</type></entry>
6234         <entry>Current date;
6235          see <xref linkend="functions-datetime-current">
6236         </entry>
6237         <entry></entry>
6238         <entry></entry>
6239        </row>
6240
6241        <row>
6242         <entry>
6243          <indexterm>
6244           <primary>current_time</primary>
6245          </indexterm>
6246          <literal><function>current_time</function></literal>
6247         </entry>
6248         <entry><type>time with time zone</type></entry>
6249         <entry>Current time of day;
6250          see <xref linkend="functions-datetime-current">
6251         </entry>
6252         <entry></entry>
6253         <entry></entry>
6254        </row>
6255
6256        <row>
6257         <entry>
6258          <indexterm>
6259           <primary>current_timestamp</primary>
6260          </indexterm>
6261          <literal><function>current_timestamp</function></literal>
6262         </entry>
6263         <entry><type>timestamp with time zone</type></entry>
6264         <entry>Current date and time (start of current transaction);
6265          see <xref linkend="functions-datetime-current">
6266         </entry>
6267         <entry></entry>
6268         <entry></entry>
6269        </row>
6270
6271        <row>
6272         <entry>
6273          <indexterm>
6274           <primary>date_part</primary>
6275          </indexterm>
6276          <literal><function>date_part(<type>text</type>, <type>timestamp</type>)</function></literal>
6277         </entry>
6278         <entry><type>double precision</type></entry>
6279         <entry>Get subfield (equivalent to <function>extract</function>);
6280          see <xref linkend="functions-datetime-extract">
6281         </entry>
6282         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6283         <entry><literal>20</literal></entry>
6284        </row>
6285
6286        <row>
6287         <entry><literal><function>date_part(<type>text</type>, <type>interval</type>)</function></literal></entry>
6288         <entry><type>double precision</type></entry>
6289         <entry>Get subfield (equivalent to
6290          <function>extract</function>); see <xref linkend="functions-datetime-extract">
6291         </entry>
6292         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
6293         <entry><literal>3</literal></entry>
6294        </row>
6295
6296        <row>
6297         <entry>
6298          <indexterm>
6299           <primary>date_trunc</primary>
6300          </indexterm>
6301          <literal><function>date_trunc(<type>text</type>, <type>timestamp</type>)</function></literal>
6302         </entry>
6303         <entry><type>timestamp</type></entry>
6304         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
6305         </entry>
6306         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6307         <entry><literal>2001-02-16 20:00:00</literal></entry>
6308        </row>
6309
6310        <row>
6311         <entry>
6312          <indexterm>
6313           <primary>extract</primary>
6314          </indexterm>
6315          <literal><function>extract</function>(<parameter>field</parameter> from
6316          <type>timestamp</type>)</literal>
6317         </entry>
6318         <entry><type>double precision</type></entry>
6319         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6320         </entry>
6321         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
6322         <entry><literal>20</literal></entry>
6323        </row>
6324
6325        <row>
6326         <entry><literal><function>extract</function>(<parameter>field</parameter> from
6327          <type>interval</type>)</literal></entry>
6328         <entry><type>double precision</type></entry>
6329         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6330         </entry>
6331         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
6332         <entry><literal>3</literal></entry>
6333        </row>
6334
6335        <row>
6336         <entry>
6337          <indexterm>
6338           <primary>isfinite</primary>
6339          </indexterm>
6340          <literal><function>isfinite(<type>date</type>)</function></literal>
6341         </entry>
6342         <entry><type>boolean</type></entry>
6343         <entry>Test for finite date (not +/-infinity)</entry>
6344         <entry><literal>isfinite(date '2001-02-16')</literal></entry>
6345         <entry><literal>true</literal></entry>
6346        </row>
6347
6348        <row>
6349         <entry><literal><function>isfinite(<type>timestamp</type>)</function></literal></entry>
6350         <entry><type>boolean</type></entry>
6351         <entry>Test for finite time stamp (not +/-infinity)</entry>
6352         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
6353         <entry><literal>true</literal></entry>
6354        </row>
6355
6356        <row>
6357         <entry><literal><function>isfinite(<type>interval</type>)</function></literal></entry>
6358         <entry><type>boolean</type></entry>
6359         <entry>Test for finite interval</entry>
6360         <entry><literal>isfinite(interval '4 hours')</literal></entry>
6361         <entry><literal>true</literal></entry>
6362        </row>
6363
6364        <row>
6365         <entry>
6366          <indexterm>
6367           <primary>justify_days</primary>
6368          </indexterm>
6369          <literal><function>justify_days(<type>interval</type>)</function></literal>
6370         </entry>
6371         <entry><type>interval</type></entry>
6372         <entry>Adjust interval so 30-day time periods are represented as months</entry>
6373         <entry><literal>justify_days(interval '35 days')</literal></entry>
6374         <entry><literal>1 mon 5 days</literal></entry>
6375        </row>
6376
6377        <row>
6378         <entry>
6379          <indexterm>
6380           <primary>justify_hours</primary>
6381          </indexterm>
6382          <literal><function>justify_hours(<type>interval</type>)</function></literal>
6383         </entry>
6384         <entry><type>interval</type></entry>
6385         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
6386         <entry><literal>justify_hours(interval '27 hours')</literal></entry>
6387         <entry><literal>1 day 03:00:00</literal></entry>
6388        </row>
6389
6390        <row>
6391         <entry>
6392          <indexterm>
6393           <primary>justify_interval</primary>
6394          </indexterm>
6395          <literal><function>justify_interval(<type>interval</type>)</function></literal>
6396         </entry>
6397         <entry><type>interval</type></entry>
6398         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
6399         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
6400         <entry><literal>29 days 23:00:00</literal></entry>
6401        </row>
6402
6403        <row>
6404         <entry>
6405          <indexterm>
6406           <primary>localtime</primary>
6407          </indexterm>
6408          <literal><function>localtime</function></literal>
6409         </entry>
6410         <entry><type>time</type></entry>
6411         <entry>Current time of day;
6412          see <xref linkend="functions-datetime-current">
6413         </entry>
6414         <entry></entry>
6415         <entry></entry>
6416        </row>
6417
6418        <row>
6419         <entry>
6420          <indexterm>
6421           <primary>localtimestamp</primary>
6422          </indexterm>
6423          <literal><function>localtimestamp</function></literal>
6424         </entry>
6425         <entry><type>timestamp</type></entry>
6426         <entry>Current date and time (start of current transaction);
6427          see <xref linkend="functions-datetime-current">
6428         </entry>
6429         <entry></entry>
6430         <entry></entry>
6431        </row>
6432
6433        <row>
6434         <entry>
6435          <indexterm>
6436           <primary>now</primary>
6437          </indexterm>
6438          <literal><function>now()</function></literal>
6439         </entry>
6440         <entry><type>timestamp with time zone</type></entry>
6441         <entry>Current date and time (start of current transaction);
6442          see <xref linkend="functions-datetime-current">
6443         </entry>
6444         <entry></entry>
6445         <entry></entry>
6446        </row>
6447
6448        <row>
6449         <entry>
6450          <indexterm>
6451           <primary>statement_timestamp</primary>
6452          </indexterm>
6453          <literal><function>statement_timestamp()</function></literal>
6454         </entry>
6455         <entry><type>timestamp with time zone</type></entry>
6456         <entry>Current date and time (start of current statement);
6457          see <xref linkend="functions-datetime-current">
6458         </entry>
6459         <entry></entry>
6460         <entry></entry>
6461        </row>
6462
6463        <row>
6464         <entry>
6465          <indexterm>
6466           <primary>timeofday</primary>
6467          </indexterm>
6468          <literal><function>timeofday()</function></literal>
6469         </entry>
6470         <entry><type>text</type></entry>
6471         <entry>Current date and time
6472          (like <function>clock_timestamp</>, but as a <type>text</> string);
6473          see <xref linkend="functions-datetime-current">
6474         </entry>
6475         <entry></entry>
6476         <entry></entry>
6477        </row>
6478
6479        <row>
6480         <entry>
6481          <indexterm>
6482           <primary>transaction_timestamp</primary>
6483          </indexterm>
6484          <literal><function>transaction_timestamp()</function></literal>
6485         </entry>
6486         <entry><type>timestamp with time zone</type></entry>
6487         <entry>Current date and time (start of current transaction);
6488          see <xref linkend="functions-datetime-current">
6489         </entry>
6490         <entry></entry>
6491         <entry></entry>
6492        </row>
6493       </tbody>
6494      </tgroup>
6495     </table>
6496
6497    <para>
6498     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6499     supported:
6500 <synopsis>
6501 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6502 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6503 </synopsis>
6504     This expression yields true when two time periods (defined by their
6505     endpoints) overlap, false when they do not overlap.  The endpoints
6506     can be specified as pairs of dates, times, or time stamps; or as
6507     a date, time, or time stamp followed by an interval.  When a pair
6508     of values is provided, either the start or the end can be written
6509     first; <literal>OVERLAPS</> automatically takes the earlier value
6510     of the pair as the start.  Each time period is considered to
6511     represent the half-open interval <replaceable>start</> <literal>&lt;=</>
6512     <replaceable>time</> <literal>&lt;</> <replaceable>end</>, unless
6513     <replaceable>start</> and <replaceable>end</> are equal in which case it
6514     represents that single time instant.  This means for instance that two
6515     time periods with only an endpoint in common do not overlap.
6516    </para>
6517
6518 <screen>
6519 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6520        (DATE '2001-10-30', DATE '2002-10-30');
6521 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6522 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6523        (DATE '2001-10-30', DATE '2002-10-30');
6524 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6525 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
6526        (DATE '2001-10-30', DATE '2001-10-31');
6527 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6528 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
6529        (DATE '2001-10-30', DATE '2001-10-31');
6530 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6531 </screen>
6532
6533   <para>
6534    When adding an <type>interval</type> value to (or subtracting an
6535    <type>interval</type> value from) a <type>timestamp with time zone</type>
6536    value, the days component advances (or decrements) the date of the
6537    <type>timestamp with time zone</type> by the indicated number of days.
6538    Across daylight saving time changes (with the session time zone set to a
6539    time zone that recognizes DST), this means <literal>interval '1 day'</literal>
6540    does not necessarily equal <literal>interval '24 hours'</literal>.
6541    For example, with the session time zone set to <literal>CST7CDT</literal>,
6542    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
6543    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>,
6544    while adding <literal>interval '24 hours'</literal> to the same initial
6545    <type>timestamp with time zone</type> produces
6546    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6547    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone
6548    <literal>CST7CDT</literal>.
6549   </para>
6550
6551   <para>
6552    Note there can be ambiguity in the <literal>months</> returned by
6553    <function>age</> because different months have a different number of
6554    days.  <productname>PostgreSQL</>'s approach uses the month from the
6555    earlier of the two dates when calculating partial months.  For example,
6556    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6557    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6558    days</> because May has 31 days, while April has only 30.
6559   </para>
6560
6561   <sect2 id="functions-datetime-extract">
6562    <title><function>EXTRACT</function>, <function>date_part</function></title>
6563
6564    <indexterm>
6565     <primary>date_part</primary>
6566    </indexterm>
6567    <indexterm>
6568     <primary>extract</primary>
6569    </indexterm>
6570
6571 <synopsis>
6572 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6573 </synopsis>
6574
6575    <para>
6576     The <function>extract</function> function retrieves subfields
6577     such as year or hour from date/time values.
6578     <replaceable>source</replaceable> must be a value expression of
6579     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6580     (Expressions of type <type>date</type> are
6581     cast to <type>timestamp</type> and can therefore be used as
6582     well.)  <replaceable>field</replaceable> is an identifier or
6583     string that selects what field to extract from the source value.
6584     The <function>extract</function> function returns values of type
6585     <type>double precision</type>.
6586     The following are valid field names:
6587
6588     <!-- alphabetical -->
6589     <variablelist>
6590      <varlistentry>
6591       <term><literal>century</literal></term>
6592       <listitem>
6593        <para>
6594         The century
6595        </para>
6596
6597 <screen>
6598 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6599 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6600 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6601 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6602 </screen>
6603
6604        <para>
6605         The first century starts at 0001-01-01 00:00:00 AD, although
6606         they did not know it at the time. This definition applies to all
6607         Gregorian calendar countries. There is no century number 0,
6608         you go from -1 century to 1 century.
6609
6610         If you disagree with this, please write your complaint to:
6611         Pope, Cathedral Saint-Peter of Roma, Vatican.
6612        </para>
6613
6614        <para>
6615         <productname>PostgreSQL</productname> releases before 8.0 did not
6616         follow the conventional numbering of centuries, but just returned
6617         the year field divided by 100.
6618        </para>
6619       </listitem>
6620      </varlistentry>
6621
6622      <varlistentry>
6623       <term><literal>day</literal></term>
6624       <listitem>
6625        <para>
6626         For <type>timestamp</type> values, the day (of the month) field
6627         (1 - 31) ; for <type>interval</type> values, the number of days
6628        </para>
6629
6630 <screen>
6631 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6632 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6633
6634 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
6635 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6636 </screen>
6637
6638
6639
6640       </listitem>
6641      </varlistentry>
6642
6643      <varlistentry>
6644       <term><literal>decade</literal></term>
6645       <listitem>
6646        <para>
6647         The year field divided by 10
6648        </para>
6649
6650 <screen>
6651 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6652 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6653 </screen>
6654       </listitem>
6655      </varlistentry>
6656
6657      <varlistentry>
6658       <term><literal>dow</literal></term>
6659       <listitem>
6660        <para>
6661         The day of the week as Sunday(<literal>0</>) to
6662         Saturday(<literal>6</>)
6663        </para>
6664
6665 <screen>
6666 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6667 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6668 </screen>
6669        <para>
6670         Note that <function>extract</function>'s day of the week numbering
6671         differs from that of the <function>to_char(...,
6672         'D')</function> function.
6673        </para>
6674
6675       </listitem>
6676      </varlistentry>
6677
6678      <varlistentry>
6679       <term><literal>doy</literal></term>
6680       <listitem>
6681        <para>
6682         The day of the year (1 - 365/366)
6683        </para>
6684
6685 <screen>
6686 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6687 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6688 </screen>
6689       </listitem>
6690      </varlistentry>
6691
6692      <varlistentry>
6693       <term><literal>epoch</literal></term>
6694       <listitem>
6695        <para>
6696         For <type>date</type> and <type>timestamp</type> values, the
6697         number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
6698         for <type>interval</type> values, the total number
6699         of seconds in the interval
6700        </para>
6701
6702 <screen>
6703 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
6704 <lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput>
6705
6706 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6707 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6708 </screen>
6709
6710        <para>
6711         Here is how you can convert an epoch value back to a time
6712         stamp:
6713        </para>
6714 <screen>
6715 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second';
6716 </screen>
6717        <para>
6718         (The <function>to_timestamp</> function encapsulates the above
6719         conversion.)
6720        </para>
6721       </listitem>
6722      </varlistentry>
6723
6724      <varlistentry>
6725       <term><literal>hour</literal></term>
6726       <listitem>
6727        <para>
6728         The hour field (0 - 23)
6729        </para>
6730
6731 <screen>
6732 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6733 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6734 </screen>
6735       </listitem>
6736      </varlistentry>
6737
6738      <varlistentry>
6739       <term><literal>isodow</literal></term>
6740       <listitem>
6741        <para>
6742         The day of the week as Monday(<literal>1</>) to
6743         Sunday(<literal>7</>)
6744        </para>
6745
6746 <screen>
6747 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6748 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6749 </screen>
6750        <para>
6751         This is identical to <literal>dow</> except for Sunday.  This
6752         matches the <acronym>ISO</> 8601 day of the week numbering.
6753        </para>
6754
6755       </listitem>
6756      </varlistentry>
6757
6758      <varlistentry>
6759       <term><literal>isoyear</literal></term>
6760       <listitem>
6761        <para>
6762         The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals)
6763        </para>
6764
6765 <screen>
6766 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6767 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6768 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6769 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6770 </screen>
6771
6772        <para>
6773         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.
6774        </para>
6775        <para>
6776         This field is not available in PostgreSQL releases prior to 8.3.
6777        </para>
6778       </listitem>
6779      </varlistentry>
6780
6781      <varlistentry>
6782       <term><literal>microseconds</literal></term>
6783       <listitem>
6784        <para>
6785         The seconds field, including fractional parts, multiplied by 1
6786         000 000;  note that this includes full seconds
6787        </para>
6788
6789 <screen>
6790 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6791 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6792 </screen>
6793       </listitem>
6794      </varlistentry>
6795
6796      <varlistentry>
6797       <term><literal>millennium</literal></term>
6798       <listitem>
6799        <para>
6800         The millennium
6801        </para>
6802
6803 <screen>
6804 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6805 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6806 </screen>
6807
6808        <para>
6809         Years in the 1900s are in the second millennium.
6810         The third millennium started January 1, 2001.
6811        </para>
6812
6813        <para>
6814         <productname>PostgreSQL</productname> releases before 8.0 did not
6815         follow the conventional numbering of millennia, but just returned
6816         the year field divided by 1000.
6817        </para>
6818       </listitem>
6819      </varlistentry>
6820
6821      <varlistentry>
6822       <term><literal>milliseconds</literal></term>
6823       <listitem>
6824        <para>
6825         The seconds field, including fractional parts, multiplied by
6826         1000.  Note that this includes full seconds.
6827        </para>
6828
6829 <screen>
6830 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6831 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6832 </screen>
6833       </listitem>
6834      </varlistentry>
6835
6836      <varlistentry>
6837       <term><literal>minute</literal></term>
6838       <listitem>
6839        <para>
6840         The minutes field (0 - 59)
6841        </para>
6842
6843 <screen>
6844 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6845 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6846 </screen>
6847       </listitem>
6848      </varlistentry>
6849
6850      <varlistentry>
6851       <term><literal>month</literal></term>
6852       <listitem>
6853        <para>
6854         For <type>timestamp</type> values, the number of the month
6855         within the year (1 - 12) ; for <type>interval</type> values,
6856         the number of months, modulo 12 (0 - 11)
6857        </para>
6858
6859 <screen>
6860 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6861 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6862
6863 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6864 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6865
6866 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6867 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6868 </screen>
6869       </listitem>
6870      </varlistentry>
6871
6872      <varlistentry>
6873       <term><literal>quarter</literal></term>
6874       <listitem>
6875        <para>
6876         The quarter of the year (1 - 4) that the date is in
6877        </para>
6878
6879 <screen>
6880 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6881 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6882 </screen>
6883       </listitem>
6884      </varlistentry>
6885
6886      <varlistentry>
6887       <term><literal>second</literal></term>
6888       <listitem>
6889        <para>
6890         The seconds field, including fractional parts (0 -
6891         59<footnote><simpara>60 if leap seconds are
6892         implemented by the operating system</simpara></footnote>)
6893        </para>
6894
6895 <screen>
6896 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6897 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6898
6899 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6900 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6901 </screen>
6902       </listitem>
6903      </varlistentry>
6904      <varlistentry>
6905       <term><literal>timezone</literal></term>
6906       <listitem>
6907        <para>
6908         The time zone offset from UTC, measured in seconds.  Positive values
6909         correspond to time zones east of UTC, negative values to
6910         zones west of UTC.  (Technically,
6911         <productname>PostgreSQL</productname> uses <acronym>UT1</> because
6912         leap seconds are not handled.)
6913        </para>
6914       </listitem>
6915      </varlistentry>
6916
6917      <varlistentry>
6918       <term><literal>timezone_hour</literal></term>
6919       <listitem>
6920        <para>
6921         The hour component of the time zone offset
6922        </para>
6923       </listitem>
6924      </varlistentry>
6925
6926      <varlistentry>
6927       <term><literal>timezone_minute</literal></term>
6928       <listitem>
6929        <para>
6930         The minute component of the time zone offset
6931        </para>
6932       </listitem>
6933      </varlistentry>
6934
6935      <varlistentry>
6936       <term><literal>week</literal></term>
6937       <listitem>
6938        <para>
6939         The number of the week of the year that the day is in.  By definition
6940         (<acronym>ISO</acronym> 8601), the first week of a year
6941         contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
6942         week starts on Monday.)  In other words, the first Thursday of
6943         a year is in week 1 of that year.
6944        </para>
6945        <para>
6946         Because of this, it is possible for early January dates to be part of the
6947         52nd or 53rd week of the previous year.  For example, <literal>2005-01-01</>
6948         is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of
6949         the 52nd week of year 2005.
6950        </para>
6951
6952 <screen>
6953 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6954 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6955 </screen>
6956       </listitem>
6957      </varlistentry>
6958
6959      <varlistentry>
6960       <term><literal>year</literal></term>
6961       <listitem>
6962        <para>
6963         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting
6964         <literal>BC</> years from <literal>AD</> years should be done with care.
6965        </para>
6966
6967 <screen>
6968 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6969 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6970 </screen>
6971       </listitem>
6972      </varlistentry>
6973
6974     </variablelist>
6975    </para>
6976
6977    <para>
6978     The <function>extract</function> function is primarily intended
6979     for computational processing.  For formatting date/time values for
6980     display, see <xref linkend="functions-formatting">.
6981    </para>
6982
6983    <para>
6984     The <function>date_part</function> function is modeled on the traditional
6985     <productname>Ingres</productname> equivalent to the
6986     <acronym>SQL</acronym>-standard function <function>extract</function>:
6987 <synopsis>
6988 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6989 </synopsis>
6990     Note that here the <replaceable>field</replaceable> parameter needs to
6991     be a string value, not a name.  The valid field names for
6992     <function>date_part</function> are the same as for
6993     <function>extract</function>.
6994    </para>
6995
6996 <screen>
6997 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
6998 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6999
7000 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
7001 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
7002 </screen>
7003
7004   </sect2>
7005
7006   <sect2 id="functions-datetime-trunc">
7007    <title><function>date_trunc</function></title>
7008
7009    <indexterm>
7010     <primary>date_trunc</primary>
7011    </indexterm>
7012
7013    <para>
7014     The function <function>date_trunc</function> is conceptually
7015     similar to the <function>trunc</function> function for numbers.
7016    </para>
7017
7018    <para>
7019 <synopsis>
7020 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
7021 </synopsis>
7022     <replaceable>source</replaceable> is a value expression of type
7023     <type>timestamp</type> or <type>interval</>.
7024     (Values of type <type>date</type> and
7025     <type>time</type> are cast automatically to <type>timestamp</type> or
7026     <type>interval</>, respectively.)
7027     <replaceable>field</replaceable> selects to which precision to
7028     truncate the input value.  The return value is of type
7029     <type>timestamp</type> or <type>interval</>
7030     with all fields that are less significant than the
7031     selected one set to zero (or one, for day and month).
7032    </para>
7033
7034    <para>
7035     Valid values for <replaceable>field</replaceable> are:
7036     <simplelist>
7037      <member><literal>microseconds</literal></member>
7038      <member><literal>milliseconds</literal></member>
7039      <member><literal>second</literal></member>
7040      <member><literal>minute</literal></member>
7041      <member><literal>hour</literal></member>
7042      <member><literal>day</literal></member>
7043      <member><literal>week</literal></member>
7044      <member><literal>month</literal></member>
7045      <member><literal>quarter</literal></member>
7046      <member><literal>year</literal></member>
7047      <member><literal>decade</literal></member>
7048      <member><literal>century</literal></member>
7049      <member><literal>millennium</literal></member>
7050     </simplelist>
7051    </para>
7052
7053    <para>
7054     Examples:
7055 <screen>
7056 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
7057 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
7058
7059 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
7060 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
7061 </screen>
7062    </para>
7063   </sect2>
7064
7065   <sect2 id="functions-datetime-zoneconvert">
7066    <title><literal>AT TIME ZONE</literal></title>
7067
7068    <indexterm>
7069     <primary>time zone</primary>
7070     <secondary>conversion</secondary>
7071    </indexterm>
7072
7073    <indexterm>
7074     <primary>AT TIME ZONE</primary>
7075    </indexterm>
7076
7077    <para>
7078     The <literal>AT TIME ZONE</literal> construct allows conversions
7079     of time stamps to different time zones.  <xref
7080     linkend="functions-datetime-zoneconvert-table"> shows its
7081     variants.
7082    </para>
7083
7084     <table id="functions-datetime-zoneconvert-table">
7085      <title><literal>AT TIME ZONE</literal> Variants</title>
7086      <tgroup cols="3">
7087       <thead>
7088        <row>
7089         <entry>Expression</entry>
7090         <entry>Return Type</entry>
7091         <entry>Description</entry>
7092        </row>
7093       </thead>
7094
7095       <tbody>
7096        <row>
7097         <entry>
7098          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7099         </entry>
7100         <entry><type>timestamp with time zone</type></entry>
7101         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
7102        </row>
7103
7104        <row>
7105         <entry>
7106          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7107         </entry>
7108         <entry><type>timestamp without time zone</type></entry>
7109         <entry>Convert given time stamp <emphasis>with time zone</> to the new time
7110         zone, with no time zone designation</entry>
7111        </row>
7112
7113        <row>
7114         <entry>
7115          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7116         </entry>
7117         <entry><type>time with time zone</type></entry>
7118         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
7119        </row>
7120       </tbody>
7121      </tgroup>
7122     </table>
7123
7124    <para>
7125     In these expressions, the desired time zone <replaceable>zone</> can be
7126     specified either as a text string (e.g., <literal>'PST'</literal>)
7127     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
7128     In the text case, a time zone name can be specified in any of the ways
7129     described in <xref linkend="datatype-timezones">.
7130    </para>
7131
7132    <para>
7133     Examples (assuming the local time zone is <literal>PST8PDT</>):
7134 <screen>
7135 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
7136 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
7137
7138 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
7139 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
7140 </screen>
7141     The first example takes a time stamp without time zone and interprets it as MST time
7142     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes
7143     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
7144    </para>
7145
7146    <para>
7147     The function <literal><function>timezone</function>(<replaceable>zone</>,
7148     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
7149     <literal><replaceable>timestamp</> AT TIME ZONE
7150     <replaceable>zone</></literal>.
7151    </para>
7152   </sect2>
7153
7154   <sect2 id="functions-datetime-current">
7155    <title>Current Date/Time</title>
7156
7157    <indexterm>
7158     <primary>date</primary>
7159     <secondary>current</secondary>
7160    </indexterm>
7161
7162    <indexterm>
7163     <primary>time</primary>
7164     <secondary>current</secondary>
7165    </indexterm>
7166
7167    <para>
7168     <productname>PostgreSQL</productname> provides a number of functions
7169     that return values related to the current date and time.  These
7170     SQL-standard functions all return values based on the start time of
7171     the current transaction:
7172 <synopsis>
7173 CURRENT_DATE
7174 CURRENT_TIME
7175 CURRENT_TIMESTAMP
7176 CURRENT_TIME(<replaceable>precision</replaceable>)
7177 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
7178 LOCALTIME
7179 LOCALTIMESTAMP
7180 LOCALTIME(<replaceable>precision</replaceable>)
7181 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
7182 </synopsis>
7183     </para>
7184
7185     <para>
7186      <function>CURRENT_TIME</function> and
7187      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
7188      <function>LOCALTIME</function> and
7189      <function>LOCALTIMESTAMP</function> deliver values without time zone.
7190     </para>
7191
7192     <para>
7193      <function>CURRENT_TIME</function>,
7194      <function>CURRENT_TIMESTAMP</function>,
7195      <function>LOCALTIME</function>, and
7196      <function>LOCALTIMESTAMP</function>
7197      can optionally take
7198      a precision parameter, which causes the result to be rounded
7199      to that many fractional digits in the seconds field.  Without a precision parameter,
7200      the result is given to the full available precision.
7201     </para>
7202
7203    <para>
7204     Some examples:
7205 <screen>
7206 SELECT CURRENT_TIME;
7207 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
7208
7209 SELECT CURRENT_DATE;
7210 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
7211
7212 SELECT CURRENT_TIMESTAMP;
7213 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
7214
7215 SELECT CURRENT_TIMESTAMP(2);
7216 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
7217
7218 SELECT LOCALTIMESTAMP;
7219 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
7220 </screen>
7221    </para>
7222
7223    <para>
7224     Since these functions return
7225     the start time of the current transaction, their values do not
7226     change during the transaction. This is considered a feature:
7227     the intent is to allow a single transaction to have a consistent
7228     notion of the <quote>current</quote> time, so that multiple
7229     modifications within the same transaction bear the same
7230     time stamp.
7231    </para>
7232
7233    <note>
7234     <para>
7235      Other database systems might advance these values more
7236      frequently.
7237     </para>
7238    </note>
7239
7240    <para>
7241     <productname>PostgreSQL</productname> also provides functions that
7242     return the start time of the current statement, as well as the actual
7243     current time at the instant the function is called.  The complete list
7244     of non-SQL-standard time functions is:
7245 <synopsis>
7246 transaction_timestamp()
7247 statement_timestamp()
7248 clock_timestamp()
7249 timeofday()
7250 now()
7251 </synopsis>
7252    </para>
7253
7254    <para>
7255     <function>transaction_timestamp()</> is equivalent to
7256     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
7257     what it returns.
7258     <function>statement_timestamp()</> returns the start time of the current
7259     statement (more specifically, the time of receipt of the latest command
7260     message from the client).
7261     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
7262     return the same value during the first command of a transaction, but might
7263     differ during subsequent commands.
7264     <function>clock_timestamp()</> returns the actual current time, and
7265     therefore its value changes even within a single SQL command.
7266     <function>timeofday()</> is a historical
7267     <productname>PostgreSQL</productname> function.  Like
7268     <function>clock_timestamp()</>, it returns the actual current time,
7269     but as a formatted <type>text</> string rather than a <type>timestamp
7270     with time zone</> value.
7271     <function>now()</> is a traditional <productname>PostgreSQL</productname>
7272     equivalent to <function>transaction_timestamp()</function>.
7273    </para>
7274
7275    <para>
7276     All the date/time data types also accept the special literal value
7277     <literal>now</literal> to specify the current date and time (again,
7278     interpreted as the transaction start time).  Thus,
7279     the following three all return the same result:
7280 <programlisting>
7281 SELECT CURRENT_TIMESTAMP;
7282 SELECT now();
7283 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
7284 </programlisting>
7285    </para>
7286
7287     <tip>
7288      <para>
7289       You do not want to use the third form when specifying a <literal>DEFAULT</>
7290       clause while creating a table.  The system will convert <literal>now</literal>
7291       to a <type>timestamp</type> as soon as the constant is parsed, so that when
7292       the default value is needed,
7293       the time of the table creation would be used!  The first two
7294       forms will not be evaluated until the default value is used,
7295       because they are function calls.  Thus they will give the desired
7296       behavior of defaulting to the time of row insertion.
7297      </para>
7298     </tip>
7299   </sect2>
7300
7301   <sect2 id="functions-datetime-delay">
7302    <title>Delaying Execution</title>
7303
7304    <indexterm>
7305     <primary>pg_sleep</primary>
7306    </indexterm>
7307    <indexterm>
7308     <primary>sleep</primary>
7309    </indexterm>
7310    <indexterm>
7311     <primary>delay</primary>
7312    </indexterm>
7313
7314    <para>
7315     The following function is available to delay execution of the server
7316     process:
7317 <synopsis>
7318 pg_sleep(<replaceable>seconds</replaceable>)
7319 </synopsis>
7320
7321     <function>pg_sleep</function> makes the current session's process
7322     sleep until <replaceable>seconds</replaceable> seconds have
7323     elapsed.  <replaceable>seconds</replaceable> is a value of type
7324     <type>double precision</>, so fractional-second delays can be specified.
7325     For example:
7326
7327 <programlisting>
7328 SELECT pg_sleep(1.5);
7329 </programlisting>
7330    </para>
7331
7332    <note>
7333      <para>
7334       The effective resolution of the sleep interval is platform-specific;
7335       0.01 seconds is a common value.  The sleep delay will be at least as long
7336       as specified. It might be longer depending on factors such as server load.
7337      </para>
7338    </note>
7339
7340    <warning>
7341      <para>
7342       Make sure that your session does not hold more locks than necessary
7343       when calling <function>pg_sleep</function>.  Otherwise other sessions
7344       might have to wait for your sleeping process, slowing down the entire
7345       system.
7346      </para>
7347    </warning>
7348   </sect2>
7349
7350  </sect1>
7351
7352
7353  <sect1 id="functions-enum">
7354   <title>Enum Support Functions</title>
7355
7356   <para>
7357    For enum types (described in <xref linkend="datatype-enum">),
7358    there are several functions that allow cleaner programming without
7359    hard-coding particular values of an enum type.
7360    These are listed in <xref linkend="functions-enum-table">. The examples
7361    assume an enum type created as:
7362
7363 <programlisting>
7364 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
7365 </programlisting>
7366
7367   </para>
7368
7369   <table id="functions-enum-table">
7370     <title>Enum Support Functions</title>
7371     <tgroup cols="4">
7372      <thead>
7373       <row>
7374        <entry>Function</entry>
7375        <entry>Description</entry>
7376        <entry>Example</entry>
7377        <entry>Example Result</entry>
7378       </row>
7379      </thead>
7380      <tbody>
7381       <row>
7382        <entry>
7383          <indexterm>
7384           <primary>enum_first</primary>
7385          </indexterm>
7386          <literal>enum_first(anyenum)</literal>
7387        </entry>
7388        <entry>Returns the first value of the input enum type</entry>
7389        <entry><literal>enum_first(null::rainbow)</literal></entry>
7390        <entry><literal>red</literal></entry>
7391       </row>
7392       <row>
7393        <entry>
7394          <indexterm>
7395           <primary>enum_last</primary>
7396          </indexterm>
7397          <literal>enum_last(anyenum)</literal>
7398        </entry>
7399        <entry>Returns the last value of the input enum type</entry>
7400        <entry><literal>enum_last(null::rainbow)</literal></entry>
7401        <entry><literal>purple</literal></entry>
7402       </row>
7403       <row>
7404        <entry>
7405          <indexterm>
7406           <primary>enum_range</primary>
7407          </indexterm>
7408          <literal>enum_range(anyenum)</literal>
7409        </entry>
7410        <entry>Returns all values of the input enum type in an ordered array</entry>
7411        <entry><literal>enum_range(null::rainbow)</literal></entry>
7412        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
7413       </row>
7414       <row>
7415        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
7416        <entry morerows="2">
7417         Returns the range between the two given enum values, as an ordered
7418         array. The values must be from the same enum type. If the first
7419         parameter is null, the result will start with the first value of
7420         the enum type.
7421         If the second parameter is null, the result will end with the last
7422         value of the enum type.
7423        </entry>
7424        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
7425        <entry><literal>{orange,yellow,green}</literal></entry>
7426       </row>
7427       <row>
7428        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
7429        <entry><literal>{red,orange,yellow,green}</literal></entry>
7430       </row>
7431       <row>
7432        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
7433        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
7434       </row>
7435      </tbody>
7436     </tgroup>
7437    </table>
7438
7439    <para>
7440     Notice that except for the two-argument form of <function>enum_range</>,
7441     these functions disregard the specific value passed to them; they care
7442     only about its declared data type.  Either null or a specific value of
7443     the type can be passed, with the same result.  It is more common to
7444     apply these functions to a table column or function argument than to
7445     a hardwired type name as suggested by the examples.
7446    </para>
7447  </sect1>
7448
7449  <sect1 id="functions-geometry">
7450   <title>Geometric Functions and Operators</title>
7451
7452    <para>
7453     The geometric types <type>point</type>, <type>box</type>,
7454     <type>lseg</type>, <type>line</type>, <type>path</type>,
7455     <type>polygon</type>, and <type>circle</type> have a large set of
7456     native support functions and operators, shown in <xref
7457     linkend="functions-geometry-op-table">, <xref
7458     linkend="functions-geometry-func-table">, and <xref
7459     linkend="functions-geometry-conv-table">.
7460    </para>
7461
7462    <caution>
7463     <para>
7464      Note that the <quote>same as</> operator, <literal>~=</>, represents
7465      the usual notion of equality for the <type>point</type>,
7466      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
7467      Some of these types also have an <literal>=</> operator, but
7468      <literal>=</> compares
7469      for equal <emphasis>areas</> only.  The other scalar comparison operators
7470      (<literal>&lt;=</> and so on) likewise compare areas for these types.
7471     </para>
7472    </caution>
7473
7474    <table id="functions-geometry-op-table">
7475      <title>Geometric Operators</title>
7476      <tgroup cols="3">
7477       <thead>
7478        <row>
7479         <entry>Operator</entry>
7480         <entry>Description</entry>
7481         <entry>Example</entry>
7482        </row>
7483       </thead>
7484       <tbody>
7485        <row>
7486         <entry> <literal>+</literal> </entry>
7487         <entry>Translation</entry>
7488         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
7489        </row>
7490        <row>
7491         <entry> <literal>-</literal> </entry>
7492         <entry>Translation</entry>
7493         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
7494        </row>
7495        <row>
7496         <entry> <literal>*</literal> </entry>
7497         <entry>Scaling/rotation</entry>
7498         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
7499        </row>
7500        <row>
7501         <entry> <literal>/</literal> </entry>
7502         <entry>Scaling/rotation</entry>
7503         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
7504        </row>
7505        <row>
7506         <entry> <literal>#</literal> </entry>
7507         <entry>Point or box of intersection</entry>
7508         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
7509        </row>
7510        <row>
7511         <entry> <literal>#</literal> </entry>
7512         <entry>Number of points in path or polygon</entry>
7513         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
7514        </row>
7515        <row>
7516         <entry> <literal>@-@</literal> </entry>
7517         <entry>Length or circumference</entry>
7518         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
7519        </row>
7520        <row>
7521         <entry> <literal>@@</literal> </entry>
7522         <entry>Center</entry>
7523         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
7524        </row>
7525        <row>
7526         <entry> <literal>##</literal> </entry>
7527         <entry>Closest point to first operand on second operand</entry>
7528         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
7529        </row>
7530        <row>
7531         <entry> <literal>&lt;-&gt;</literal> </entry>
7532         <entry>Distance between</entry>
7533         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
7534        </row>
7535        <row>
7536         <entry> <literal>&amp;&amp;</literal> </entry>
7537         <entry>Overlaps?  (One point in common makes this true.)</entry>
7538         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
7539        </row>
7540        <row>
7541         <entry> <literal>&lt;&lt;</literal> </entry>
7542         <entry>Is strictly left of?</entry>
7543         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
7544        </row>
7545        <row>
7546         <entry> <literal>&gt;&gt;</literal> </entry>
7547         <entry>Is strictly right of?</entry>
7548         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
7549        </row>
7550        <row>
7551         <entry> <literal>&amp;&lt;</literal> </entry>
7552         <entry>Does not extend to the right of?</entry>
7553         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
7554        </row>
7555        <row>
7556         <entry> <literal>&amp;&gt;</literal> </entry>
7557         <entry>Does not extend to the left of?</entry>
7558         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
7559        </row>
7560        <row>
7561         <entry> <literal>&lt;&lt;|</literal> </entry>
7562         <entry>Is strictly below?</entry>
7563         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
7564        </row>
7565        <row>
7566         <entry> <literal>|&gt;&gt;</literal> </entry>
7567         <entry>Is strictly above?</entry>
7568         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
7569        </row>
7570        <row>
7571         <entry> <literal>&amp;&lt;|</literal> </entry>
7572         <entry>Does not extend above?</entry>
7573         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
7574        </row>
7575        <row>
7576         <entry> <literal>|&amp;&gt;</literal> </entry>
7577         <entry>Does not extend below?</entry>
7578         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
7579        </row>
7580        <row>
7581         <entry> <literal>&lt;^</literal> </entry>
7582         <entry>Is below (allows touching)?</entry>
7583         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
7584        </row>
7585        <row>
7586         <entry> <literal>&gt;^</literal> </entry>
7587         <entry>Is above (allows touching)?</entry>
7588         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
7589        </row>
7590        <row>
7591         <entry> <literal>?#</literal> </entry>
7592         <entry>Intersects?</entry>
7593         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7594        </row>
7595        <row>
7596         <entry> <literal>?-</literal> </entry>
7597         <entry>Is horizontal?</entry>
7598         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7599        </row>
7600        <row>
7601         <entry> <literal>?-</literal> </entry>
7602         <entry>Are horizontally aligned?</entry>
7603         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7604        </row>
7605        <row>
7606         <entry> <literal>?|</literal> </entry>
7607         <entry>Is vertical?</entry>
7608         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7609        </row>
7610        <row>
7611         <entry> <literal>?|</literal> </entry>
7612         <entry>Are vertically aligned?</entry>
7613         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7614        </row>
7615        <row>
7616         <entry> <literal>?-|</literal> </entry>
7617         <entry>Is perpendicular?</entry>
7618         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7619        </row>
7620        <row>
7621         <entry> <literal>?||</literal> </entry>
7622         <entry>Are parallel?</entry>
7623         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7624        </row>
7625        <row>
7626         <entry> <literal>@&gt;</literal> </entry>
7627         <entry>Contains?</entry>
7628         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7629        </row>
7630        <row>
7631         <entry> <literal>&lt;@</literal> </entry>
7632         <entry>Contained in or on?</entry>
7633         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7634        </row>
7635        <row>
7636         <entry> <literal>~=</literal> </entry>
7637         <entry>Same as?</entry>
7638         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7639        </row>
7640       </tbody>
7641      </tgroup>
7642    </table>
7643
7644    <note>
7645     <para>
7646      Before <productname>PostgreSQL</productname> 8.2, the containment
7647      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7648      called <literal>~</> and <literal>@</>.  These names are still
7649      available, but are deprecated and will eventually be removed.
7650     </para>
7651    </note>
7652
7653    <indexterm>
7654     <primary>area</primary>
7655    </indexterm>
7656    <indexterm>
7657     <primary>center</primary>
7658    </indexterm>
7659    <indexterm>
7660     <primary>diameter</primary>
7661    </indexterm>
7662    <indexterm>
7663     <primary>height</primary>
7664    </indexterm>
7665    <indexterm>
7666     <primary>isclosed</primary>
7667    </indexterm>
7668    <indexterm>
7669     <primary>isopen</primary>
7670    </indexterm>
7671    <indexterm>
7672     <primary>length</primary>
7673    </indexterm>
7674    <indexterm>
7675     <primary>npoints</primary>
7676    </indexterm>
7677    <indexterm>
7678     <primary>pclose</primary>
7679    </indexterm>
7680    <indexterm>
7681     <primary>popen</primary>
7682    </indexterm>
7683    <indexterm>
7684     <primary>radius</primary>
7685    </indexterm>
7686    <indexterm>
7687     <primary>width</primary>
7688    </indexterm>
7689
7690    <table id="functions-geometry-func-table">
7691      <title>Geometric Functions</title>
7692      <tgroup cols="4">
7693       <thead>
7694        <row>
7695         <entry>Function</entry>
7696         <entry>Return Type</entry>
7697         <entry>Description</entry>
7698         <entry>Example</entry>
7699        </row>
7700       </thead>
7701       <tbody>
7702        <row>
7703         <entry><literal><function>area(<replaceable>object</>)</function></literal></entry>
7704         <entry><type>double precision</type></entry>
7705         <entry>area</entry>
7706         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7707        </row>
7708        <row>
7709         <entry><literal><function>center(<replaceable>object</>)</function></literal></entry>
7710         <entry><type>point</type></entry>
7711         <entry>center</entry>
7712         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7713        </row>
7714        <row>
7715         <entry><literal><function>diameter(<type>circle</>)</function></literal></entry>
7716         <entry><type>double precision</type></entry>
7717         <entry>diameter of circle</entry>
7718         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7719        </row>
7720        <row>
7721         <entry><literal><function>height(<type>box</>)</function></literal></entry>
7722         <entry><type>double precision</type></entry>
7723         <entry>vertical size of box</entry>
7724         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7725        </row>
7726        <row>
7727         <entry><literal><function>isclosed(<type>path</>)</function></literal></entry>
7728         <entry><type>boolean</type></entry>
7729         <entry>a closed path?</entry>
7730         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7731        </row>
7732        <row>
7733         <entry><literal><function>isopen(<type>path</>)</function></literal></entry>
7734         <entry><type>boolean</type></entry>
7735         <entry>an open path?</entry>
7736         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7737        </row>
7738        <row>
7739         <entry><literal><function>length(<replaceable>object</>)</function></literal></entry>
7740         <entry><type>double precision</type></entry>
7741         <entry>length</entry>
7742         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7743        </row>
7744        <row>
7745         <entry><literal><function>npoints(<type>path</>)</function></literal></entry>
7746         <entry><type>int</type></entry>
7747         <entry>number of points</entry>
7748         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7749        </row>
7750        <row>
7751         <entry><literal><function>npoints(<type>polygon</>)</function></literal></entry>
7752         <entry><type>int</type></entry>
7753         <entry>number of points</entry>
7754         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7755        </row>
7756        <row>
7757         <entry><literal><function>pclose(<type>path</>)</function></literal></entry>
7758         <entry><type>path</type></entry>
7759         <entry>convert path to closed</entry>
7760         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7761        </row>
7762 <![IGNORE[
7763 <!-- Not defined by this name. Implements the intersection operator '#' -->
7764        <row>
7765         <entry><literal><function>point(<type>lseg</>, <type>lseg</>)</function></literal></entry>
7766         <entry><type>point</type></entry>
7767         <entry>intersection</entry>
7768         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7769        </row>
7770 ]]>
7771        <row>
7772         <entry><literal><function>popen(<type>path</>)</function></literal></entry>
7773         <entry><type>path</type></entry>
7774         <entry>convert path to open</entry>
7775         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7776        </row>
7777        <row>
7778         <entry><literal><function>radius(<type>circle</type>)</function></literal></entry>
7779         <entry><type>double precision</type></entry>
7780         <entry>radius of circle</entry>
7781         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7782        </row>
7783        <row>
7784         <entry><literal><function>width(<type>box</>)</function></literal></entry>
7785         <entry><type>double precision</type></entry>
7786         <entry>horizontal size of box</entry>
7787         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7788        </row>
7789       </tbody>
7790      </tgroup>
7791    </table>
7792
7793    <table id="functions-geometry-conv-table">
7794      <title>Geometric Type Conversion Functions</title>
7795      <tgroup cols="4">
7796       <thead>
7797        <row>
7798         <entry>Function</entry>
7799         <entry>Return Type</entry>
7800         <entry>Description</entry>
7801         <entry>Example</entry>
7802        </row>
7803       </thead>
7804       <tbody>
7805        <row>
7806         <entry>
7807          <indexterm>
7808           <primary>box</primary>
7809          </indexterm>
7810          <literal><function>box(<type>circle</type>)</function></literal>
7811         </entry>
7812         <entry><type>box</type></entry>
7813         <entry>circle to box</entry>
7814         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7815        </row>
7816        <row>
7817         <entry><literal><function>box(<type>point</type>, <type>point</type>)</function></literal></entry>
7818         <entry><type>box</type></entry>
7819         <entry>points to box</entry>
7820         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7821        </row>
7822        <row>
7823         <entry><literal><function>box(<type>polygon</type>)</function></literal></entry>
7824         <entry><type>box</type></entry>
7825         <entry>polygon to box</entry>
7826         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7827        </row>
7828        <row>
7829         <entry>
7830          <indexterm>
7831           <primary>circle</primary>
7832          </indexterm>
7833          <literal><function>circle(<type>box</type>)</function></literal>
7834         </entry>
7835         <entry><type>circle</type></entry>
7836         <entry>box to circle</entry>
7837         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7838        </row>
7839        <row>
7840         <entry><literal><function>circle(<type>point</type>, <type>double precision</type>)</function></literal></entry>
7841         <entry><type>circle</type></entry>
7842         <entry>center and radius to circle</entry>
7843         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7844        </row>
7845        <row>
7846         <entry><literal><function>circle(<type>polygon</type>)</function></literal></entry>
7847         <entry><type>circle</type></entry>
7848         <entry>polygon to circle</entry>
7849         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7850        </row>
7851        <row>
7852         <entry>
7853          <indexterm>
7854           <primary>lseg</primary>
7855          </indexterm>
7856          <literal><function>lseg(<type>box</type>)</function></literal>
7857         </entry>
7858         <entry><type>lseg</type></entry>
7859         <entry>box diagonal to line segment</entry>
7860         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7861        </row>
7862        <row>
7863         <entry><literal><function>lseg(<type>point</type>, <type>point</type>)</function></literal></entry>
7864         <entry><type>lseg</type></entry>
7865         <entry>points to line segment</entry>
7866         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7867        </row>
7868        <row>
7869         <entry>
7870          <indexterm>
7871           <primary>path</primary>
7872          </indexterm>
7873          <literal><function>path(<type>polygon</type>)</function></literal>
7874         </entry>
7875         <entry><type>point</type></entry>
7876         <entry>polygon to path</entry>
7877         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7878        </row>
7879        <row>
7880         <entry>
7881          <indexterm>
7882           <primary>point</primary>
7883          </indexterm>
7884          <literal><function>point</function>(<type>double
7885          precision</type>, <type>double precision</type>)</literal>
7886         </entry>
7887         <entry><type>point</type></entry>
7888         <entry>construct point</entry>
7889         <entry><literal>point(23.4, -44.5)</literal></entry>
7890        </row>
7891        <row>
7892         <entry><literal><function>point(<type>box</type>)</function></literal></entry>
7893         <entry><type>point</type></entry>
7894         <entry>center of box</entry>
7895         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7896        </row>
7897        <row>
7898         <entry><literal><function>point(<type>circle</type>)</function></literal></entry>
7899         <entry><type>point</type></entry>
7900         <entry>center of circle</entry>
7901         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7902        </row>
7903        <row>
7904         <entry><literal><function>point(<type>lseg</type>)</function></literal></entry>
7905         <entry><type>point</type></entry>
7906         <entry>center of line segment</entry>
7907         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7908        </row>
7909        <row>
7910         <entry><literal><function>point(<type>polygon</type>)</function></literal></entry>
7911         <entry><type>point</type></entry>
7912         <entry>center of polygon</entry>
7913         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7914        </row>
7915        <row>
7916         <entry>
7917          <indexterm>
7918           <primary>polygon</primary>
7919          </indexterm>
7920          <literal><function>polygon(<type>box</type>)</function></literal>
7921         </entry>
7922         <entry><type>polygon</type></entry>
7923         <entry>box to 4-point polygon</entry>
7924         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7925        </row>
7926        <row>
7927         <entry><literal><function>polygon(<type>circle</type>)</function></literal></entry>
7928         <entry><type>polygon</type></entry>
7929         <entry>circle to 12-point polygon</entry>
7930         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7931        </row>
7932        <row>
7933         <entry><literal><function>polygon(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</function></literal></entry>
7934         <entry><type>polygon</type></entry>
7935         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
7936         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7937        </row>
7938        <row>
7939         <entry><literal><function>polygon(<type>path</type>)</function></literal></entry>
7940         <entry><type>polygon</type></entry>
7941         <entry>path to polygon</entry>
7942         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7943        </row>
7944       </tbody>
7945      </tgroup>
7946    </table>
7947
7948     <para>
7949      It is possible to access the two component numbers of a <type>point</>
7950      as though the point were an array with indexes 0 and 1.  For example, if
7951      <literal>t.p</> is a <type>point</> column then
7952      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7953      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7954      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7955      as an array of two <type>point</> values.
7956     </para>
7957
7958     <para>
7959      The <function>area</function> function works for the types
7960      <type>box</type>, <type>circle</type>, and <type>path</type>.
7961      The <function>area</function> function only works on the
7962      <type>path</type> data type if the points in the
7963      <type>path</type> are non-intersecting.  For example, the
7964      <type>path</type>
7965      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7966      will not work;  however, the following visually identical
7967      <type>path</type>
7968      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7969      will work.  If the concept of an intersecting versus
7970      non-intersecting <type>path</type> is confusing, draw both of the
7971      above <type>path</type>s side by side on a piece of graph paper.
7972     </para>
7973
7974   </sect1>
7975
7976
7977  <sect1 id="functions-net">
7978   <title>Network Address Functions and Operators</title>
7979
7980   <para>
7981    <xref linkend="cidr-inet-operators-table"> shows the operators
7982    available for the <type>cidr</type> and <type>inet</type> types.
7983    The operators <literal>&lt;&lt;</literal>,
7984    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
7985    <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
7986    consider only the network parts of the two addresses (ignoring any
7987    host part) and determine whether one network is identical to
7988    or a subnet of the other.
7989   </para>
7990
7991     <table id="cidr-inet-operators-table">
7992      <title><type>cidr</type> and <type>inet</type> Operators</title>
7993      <tgroup cols="3">
7994       <thead>
7995        <row>
7996         <entry>Operator</entry>
7997         <entry>Description</entry>
7998         <entry>Example</entry>
7999        </row>
8000       </thead>
8001       <tbody>
8002        <row>
8003         <entry> <literal>&lt;</literal> </entry>
8004         <entry>is less than</entry>
8005         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
8006        </row>
8007        <row>
8008         <entry> <literal>&lt;=</literal> </entry>
8009         <entry>is less than or equal</entry>
8010         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
8011        </row>
8012        <row>
8013         <entry> <literal>=</literal> </entry>
8014         <entry>equals</entry>
8015         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
8016        </row>
8017        <row>
8018         <entry> <literal>&gt;=</literal> </entry>
8019         <entry>is greater or equal</entry>
8020         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
8021        </row>
8022        <row>
8023         <entry> <literal>&gt;</literal> </entry>
8024         <entry>is greater than</entry>
8025         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
8026        </row>
8027        <row>
8028         <entry> <literal>&lt;&gt;</literal> </entry>
8029         <entry>is not equal</entry>
8030         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
8031        </row>
8032        <row>
8033         <entry> <literal>&lt;&lt;</literal> </entry>
8034         <entry>is contained within</entry>
8035         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
8036        </row>
8037        <row>
8038         <entry> <literal>&lt;&lt;=</literal> </entry>
8039         <entry>is contained within or equals</entry>
8040         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
8041        </row>
8042        <row>
8043         <entry> <literal>&gt;&gt;</literal> </entry>
8044         <entry>contains</entry>
8045         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
8046        </row>
8047        <row>
8048         <entry> <literal>&gt;&gt;=</literal> </entry>
8049         <entry>contains or equals</entry>
8050         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
8051        </row>
8052        <row>
8053         <entry> <literal>~</literal> </entry>
8054         <entry>bitwise NOT</entry>
8055         <entry><literal>~ inet '192.168.1.6'</literal></entry>
8056        </row>
8057        <row>
8058         <entry> <literal>&amp;</literal> </entry>
8059         <entry>bitwise AND</entry>
8060         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
8061        </row>
8062        <row>
8063         <entry> <literal>|</literal> </entry>
8064         <entry>bitwise OR</entry>
8065         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
8066        </row>
8067        <row>
8068         <entry> <literal>+</literal> </entry>
8069         <entry>addition</entry>
8070         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
8071        </row>
8072        <row>
8073         <entry> <literal>-</literal> </entry>
8074         <entry>subtraction</entry>
8075         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
8076        </row>
8077        <row>
8078         <entry> <literal>-</literal> </entry>
8079         <entry>subtraction</entry>
8080         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
8081        </row>
8082       </tbody>
8083      </tgroup>
8084     </table>
8085
8086   <para>
8087    <xref linkend="cidr-inet-functions-table"> shows the functions
8088    available for use with the <type>cidr</type> and <type>inet</type>
8089    types.  The <function>abbrev</function>, <function>host</function>,
8090    and <function>text</function>
8091    functions are primarily intended to offer alternative display
8092    formats.
8093   </para>
8094
8095     <table id="cidr-inet-functions-table">
8096      <title><type>cidr</type> and <type>inet</type> Functions</title>
8097      <tgroup cols="5">
8098       <thead>
8099        <row>
8100         <entry>Function</entry>
8101         <entry>Return Type</entry>
8102         <entry>Description</entry>
8103         <entry>Example</entry>
8104         <entry>Result</entry>
8105        </row>
8106       </thead>
8107       <tbody>
8108        <row>
8109         <entry>
8110          <indexterm>
8111           <primary>abbrev</primary>
8112          </indexterm>
8113          <literal><function>abbrev(<type>inet</type>)</function></literal>
8114         </entry>
8115         <entry><type>text</type></entry>
8116         <entry>abbreviated display format as text</entry>
8117         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
8118         <entry><literal>10.1.0.0/16</literal></entry>
8119        </row>
8120        <row>
8121         <entry><literal><function>abbrev(<type>cidr</type>)</function></literal></entry>
8122         <entry><type>text</type></entry>
8123         <entry>abbreviated display format as text</entry>
8124         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
8125         <entry><literal>10.1/16</literal></entry>
8126        </row>
8127        <row>
8128         <entry>
8129          <indexterm>
8130           <primary>broadcast</primary>
8131          </indexterm>
8132          <literal><function>broadcast(<type>inet</type>)</function></literal>
8133         </entry>
8134         <entry><type>inet</type></entry>
8135         <entry>broadcast address for network</entry>
8136         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
8137         <entry><literal>192.168.1.255/24</literal></entry>
8138        </row>
8139        <row>
8140         <entry>
8141          <indexterm>
8142           <primary>family</primary>
8143          </indexterm>
8144          <literal><function>family(<type>inet</type>)</function></literal>
8145         </entry>
8146         <entry><type>int</type></entry>
8147         <entry>extract family of address; <literal>4</literal> for IPv4,
8148          <literal>6</literal> for IPv6</entry>
8149         <entry><literal>family('::1')</literal></entry>
8150         <entry><literal>6</literal></entry>
8151        </row>
8152        <row>
8153         <entry>
8154          <indexterm>
8155           <primary>host</primary>
8156          </indexterm>
8157          <literal><function>host(<type>inet</type>)</function></literal>
8158         </entry>
8159         <entry><type>text</type></entry>
8160         <entry>extract IP address as text</entry>
8161         <entry><literal>host('192.168.1.5/24')</literal></entry>
8162         <entry><literal>192.168.1.5</literal></entry>
8163        </row>
8164        <row>
8165         <entry>
8166          <indexterm>
8167           <primary>hostmask</primary>
8168          </indexterm>
8169          <literal><function>hostmask(<type>inet</type>)</function></literal>
8170         </entry>
8171         <entry><type>inet</type></entry>
8172         <entry>construct host mask for network</entry>
8173         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
8174         <entry><literal>0.0.0.3</literal></entry>
8175        </row>
8176        <row>
8177         <entry>
8178          <indexterm>
8179           <primary>masklen</primary>
8180          </indexterm>
8181          <literal><function>masklen(<type>inet</type>)</function></literal>
8182         </entry>
8183         <entry><type>int</type></entry>
8184         <entry>extract netmask length</entry>
8185         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
8186         <entry><literal>24</literal></entry>
8187        </row>
8188        <row>
8189         <entry>
8190          <indexterm>
8191           <primary>netmask</primary>
8192          </indexterm>
8193          <literal><function>netmask(<type>inet</type>)</function></literal>
8194         </entry>
8195         <entry><type>inet</type></entry>
8196         <entry>construct netmask for network</entry>
8197         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
8198         <entry><literal>255.255.255.0</literal></entry>
8199        </row>
8200        <row>
8201         <entry>
8202          <indexterm>
8203           <primary>network</primary>
8204          </indexterm>
8205          <literal><function>network(<type>inet</type>)</function></literal>
8206         </entry>
8207         <entry><type>cidr</type></entry>
8208         <entry>extract network part of address</entry>
8209         <entry><literal>network('192.168.1.5/24')</literal></entry>
8210         <entry><literal>192.168.1.0/24</literal></entry>
8211        </row>
8212        <row>
8213         <entry>
8214          <indexterm>
8215           <primary>set_masklen</primary>
8216          </indexterm>
8217          <literal><function>set_masklen(<type>inet</type>, <type>int</type>)</function></literal>
8218         </entry>
8219         <entry><type>inet</type></entry>
8220         <entry>set netmask length for <type>inet</type> value</entry>
8221         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
8222         <entry><literal>192.168.1.5/16</literal></entry>
8223        </row>
8224        <row>
8225         <entry><literal><function>set_masklen(<type>cidr</type>, <type>int</type>)</function></literal></entry>
8226         <entry><type>cidr</type></entry>
8227         <entry>set netmask length for <type>cidr</type> value</entry>
8228         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
8229         <entry><literal>192.168.0.0/16</literal></entry>
8230        </row>
8231        <row>
8232         <entry>
8233          <indexterm>
8234           <primary>text</primary>
8235          </indexterm>
8236          <literal><function>text(<type>inet</type>)</function></literal>
8237         </entry>
8238         <entry><type>text</type></entry>
8239         <entry>extract IP address and netmask length as text</entry>
8240         <entry><literal>text(inet '192.168.1.5')</literal></entry>
8241         <entry><literal>192.168.1.5/32</literal></entry>
8242        </row>
8243       </tbody>
8244      </tgroup>
8245     </table>
8246
8247   <para>
8248    Any <type>cidr</> value can be cast to <type>inet</> implicitly
8249    or explicitly; therefore, the functions shown above as operating on
8250    <type>inet</> also work on <type>cidr</> values.  (Where there are
8251    separate functions for <type>inet</> and <type>cidr</>, it is because
8252    the behavior should be different for the two cases.)
8253    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
8254    When this is done, any bits to the right of the netmask are silently zeroed
8255    to create a valid <type>cidr</> value.
8256    In addition,
8257    you can cast a text value to <type>inet</> or <type>cidr</>
8258    using normal casting syntax: for example,
8259    <literal>inet(<replaceable>expression</>)</literal> or
8260    <literal><replaceable>colname</>::cidr</literal>.
8261   </para>
8262
8263   <para>
8264    <xref linkend="macaddr-functions-table"> shows the functions
8265    available for use with the <type>macaddr</type> type.  The function
8266    <literal><function>trunc(<type>macaddr</type>)</function></literal> returns a MAC
8267    address with the last 3 bytes set to zero.  This can be used to
8268    associate the remaining prefix with a manufacturer.
8269   </para>
8270
8271     <table id="macaddr-functions-table">
8272      <title><type>macaddr</type> Functions</title>
8273      <tgroup cols="5">
8274       <thead>
8275        <row>
8276         <entry>Function</entry>
8277         <entry>Return Type</entry>
8278         <entry>Description</entry>
8279         <entry>Example</entry>
8280         <entry>Result</entry>
8281        </row>
8282       </thead>
8283       <tbody>
8284        <row>
8285         <entry>
8286          <indexterm>
8287           <primary>trunc</primary>
8288          </indexterm>
8289          <literal><function>trunc(<type>macaddr</type>)</function></literal>
8290         </entry>
8291         <entry><type>macaddr</type></entry>
8292         <entry>set last 3 bytes to zero</entry>
8293         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
8294         <entry><literal>12:34:56:00:00:00</literal></entry>
8295        </row>
8296       </tbody>
8297      </tgroup>
8298     </table>
8299
8300    <para>
8301     The <type>macaddr</type> type also supports the standard relational
8302     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
8303     lexicographical ordering.
8304    </para>
8305
8306   </sect1>
8307
8308
8309  <sect1 id="functions-textsearch">
8310   <title>Text Search Functions and Operators</title>
8311
8312    <indexterm zone="datatype-textsearch">
8313     <primary>full text search</primary>
8314     <secondary>functions and operators</secondary>
8315    </indexterm>
8316
8317    <indexterm zone="datatype-textsearch">
8318     <primary>text search</primary>
8319     <secondary>functions and operators</secondary>
8320    </indexterm>
8321
8322   <para>
8323    <xref linkend="textsearch-operators-table">,
8324    <xref linkend="textsearch-functions-table"> and
8325    <xref linkend="textsearch-functions-debug-table">
8326    summarize the functions and operators that are provided
8327    for full text searching.  See <xref linkend="textsearch"> for a detailed
8328    explanation of <productname>PostgreSQL</productname>'s text search
8329    facility.
8330   </para>
8331
8332     <table id="textsearch-operators-table">
8333      <title>Text Search Operators</title>
8334      <tgroup cols="4">
8335       <thead>
8336        <row>
8337         <entry>Operator</entry>
8338         <entry>Description</entry>
8339         <entry>Example</entry>
8340         <entry>Result</entry>
8341        </row>
8342       </thead>
8343       <tbody>
8344        <row>
8345         <entry> <literal>@@</literal> </entry>
8346         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
8347         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
8348         <entry><literal>t</literal></entry>
8349        </row>
8350        <row>
8351         <entry> <literal>@@@</literal> </entry>
8352         <entry>deprecated synonym for <literal>@@</></entry>
8353         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
8354         <entry><literal>t</literal></entry>
8355        </row>
8356        <row>
8357         <entry> <literal>||</literal> </entry>
8358         <entry>concatenate <type>tsvector</>s</entry>
8359         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
8360         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
8361        </row>
8362        <row>
8363         <entry> <literal>&amp;&amp;</literal> </entry>
8364         <entry>AND <type>tsquery</>s together</entry>
8365         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
8366         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
8367        </row>
8368        <row>
8369         <entry> <literal>||</literal> </entry>
8370         <entry>OR <type>tsquery</>s together</entry>
8371         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
8372         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
8373        </row>
8374        <row>
8375         <entry> <literal>!!</literal> </entry>
8376         <entry>negate a <type>tsquery</></entry>
8377         <entry><literal>!! 'cat'::tsquery</literal></entry>
8378         <entry><literal>!'cat'</literal></entry>
8379        </row>
8380        <row>
8381         <entry> <literal>@&gt;</literal> </entry>
8382         <entry><type>tsquery</> contains another ?</entry>
8383         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
8384         <entry><literal>f</literal></entry>
8385        </row>
8386        <row>
8387         <entry> <literal>&lt;@</literal> </entry>
8388         <entry><type>tsquery</> is contained in ?</entry>
8389         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
8390         <entry><literal>t</literal></entry>
8391        </row>
8392       </tbody>
8393      </tgroup>
8394     </table>
8395
8396     <note>
8397      <para>
8398       The <type>tsquery</> containment operators consider only the lexemes
8399       listed in the two queries, ignoring the combining operators.
8400      </para>
8401     </note>
8402
8403     <para>
8404      In addition to the operators shown in the table, the ordinary B-tree
8405      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
8406      for types <type>tsvector</> and <type>tsquery</>.  These are not very
8407      useful for text searching but allow, for example, unique indexes to be
8408      built on columns of these types.
8409     </para>
8410
8411     <table id="textsearch-functions-table">
8412      <title>Text Search Functions</title>
8413      <tgroup cols="5">
8414       <thead>
8415        <row>
8416         <entry>Function</entry>
8417         <entry>Return Type</entry>
8418         <entry>Description</entry>
8419         <entry>Example</entry>
8420         <entry>Result</entry>
8421        </row>
8422       </thead>
8423       <tbody>
8424        <row>
8425         <entry>
8426          <indexterm>
8427           <primary>get_current_ts_config</primary>
8428          </indexterm>
8429          <literal><function>get_current_ts_config()</function></literal>
8430         </entry>
8431         <entry><type>regconfig</type></entry>
8432         <entry>get default text search configuration</entry>
8433         <entry><literal>get_current_ts_config()</literal></entry>
8434         <entry><literal>english</literal></entry>
8435        </row>
8436        <row>
8437         <entry>
8438          <indexterm>
8439           <primary>length</primary>
8440          </indexterm>
8441          <literal><function>length(<type>tsvector</>)</function></literal>
8442         </entry>
8443         <entry><type>integer</type></entry>
8444         <entry>number of lexemes in <type>tsvector</></entry>
8445         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
8446         <entry><literal>3</literal></entry>
8447        </row>
8448        <row>
8449         <entry>
8450          <indexterm>
8451           <primary>numnode</primary>
8452          </indexterm>
8453          <literal><function>numnode(<type>tsquery</>)</function></literal>
8454         </entry>
8455         <entry><type>integer</type></entry>
8456         <entry>number of lexemes plus operators in <type>tsquery</></entry>
8457         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
8458         <entry><literal>5</literal></entry>
8459        </row>
8460        <row>
8461         <entry>
8462          <indexterm>
8463           <primary>plainto_tsquery</primary>
8464          </indexterm>
8465          <literal><function>plainto_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
8466         </entry>
8467         <entry><type>tsquery</type></entry>
8468         <entry>produce <type>tsquery</> ignoring punctuation</entry>
8469         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
8470         <entry><literal>'fat' &amp; 'rat'</literal></entry>
8471        </row>
8472        <row>
8473         <entry>
8474          <indexterm>
8475           <primary>querytree</primary>
8476          </indexterm>
8477          <literal><function>querytree(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</function></literal>
8478         </entry>
8479         <entry><type>text</type></entry>
8480         <entry>get indexable part of a <type>tsquery</></entry>
8481         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
8482         <entry><literal>'foo'</literal></entry>
8483        </row>
8484        <row>
8485         <entry>
8486          <indexterm>
8487           <primary>setweight</primary>
8488          </indexterm>
8489          <literal><function>setweight(<type>tsvector</>, <type>"char"</>)</function></literal>
8490         </entry>
8491         <entry><type>tsvector</type></entry>
8492         <entry>assign weight to each element of <type>tsvector</></entry>
8493         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
8494         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
8495        </row>
8496        <row>
8497         <entry>
8498          <indexterm>
8499           <primary>strip</primary>
8500          </indexterm>
8501          <literal><function>strip(<type>tsvector</>)</function></literal>
8502         </entry>
8503         <entry><type>tsvector</type></entry>
8504         <entry>remove positions and weights from <type>tsvector</></entry>
8505         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
8506         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
8507        </row>
8508        <row>
8509         <entry>
8510          <indexterm>
8511           <primary>to_tsquery</primary>
8512          </indexterm>
8513          <literal><function>to_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
8514         </entry>
8515         <entry><type>tsquery</type></entry>
8516         <entry>normalize words and convert to <type>tsquery</></entry>
8517         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
8518         <entry><literal>'fat' &amp; 'rat'</literal></entry>
8519        </row>
8520        <row>
8521         <entry>
8522          <indexterm>
8523           <primary>to_tsvector</primary>
8524          </indexterm>
8525          <literal><function>to_tsvector(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</function></literal>
8526         </entry>
8527         <entry><type>tsvector</type></entry>
8528         <entry>reduce document text to <type>tsvector</></entry>
8529         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
8530         <entry><literal>'fat':2 'rat':3</literal></entry>
8531        </row>
8532        <row>
8533         <entry>
8534          <indexterm>
8535           <primary>ts_headline</primary>
8536          </indexterm>
8537          <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>
8538         </entry>
8539         <entry><type>text</type></entry>
8540         <entry>display a query match</entry>
8541         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
8542         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
8543        </row>
8544        <row>
8545         <entry>
8546          <indexterm>
8547           <primary>ts_rank</primary>
8548          </indexterm>
8549          <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>
8550         </entry>
8551         <entry><type>float4</type></entry>
8552         <entry>rank document for query</entry>
8553         <entry><literal>ts_rank(textsearch, query)</literal></entry>
8554         <entry><literal>0.818</literal></entry>
8555        </row>
8556        <row>
8557         <entry>
8558          <indexterm>
8559           <primary>ts_rank_cd</primary>
8560          </indexterm>
8561          <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>
8562         </entry>
8563         <entry><type>float4</type></entry>
8564         <entry>rank document for query using cover density</entry>
8565         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
8566         <entry><literal>2.01317</literal></entry>
8567        </row>
8568        <row>
8569         <entry>
8570          <indexterm>
8571           <primary>ts_rewrite</primary>
8572          </indexterm>
8573          <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>
8574         </entry>
8575         <entry><type>tsquery</type></entry>
8576         <entry>replace target with substitute within query</entry>
8577         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
8578         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
8579        </row>
8580        <row>
8581         <entry><literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</function></literal></entry>
8582         <entry><type>tsquery</type></entry>
8583         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
8584         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
8585         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
8586        </row>
8587        <row>
8588         <entry>
8589          <indexterm>
8590           <primary>tsvector_update_trigger</primary>
8591          </indexterm>
8592          <literal><function>tsvector_update_trigger()</function></literal>
8593         </entry>
8594         <entry><type>trigger</type></entry>
8595         <entry>trigger function for automatic <type>tsvector</> column update</entry>
8596         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
8597         <entry><literal></literal></entry>
8598        </row>
8599        <row>
8600         <entry>
8601          <indexterm>
8602           <primary>tsvector_update_trigger_column</primary>
8603          </indexterm>
8604          <literal><function>tsvector_update_trigger_column()</function></literal>
8605         </entry>
8606         <entry><type>trigger</type></entry>
8607         <entry>trigger function for automatic <type>tsvector</> column update</entry>
8608         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
8609         <entry><literal></literal></entry>
8610        </row>
8611       </tbody>
8612      </tgroup>
8613     </table>
8614
8615   <note>
8616    <para>
8617     All the text search functions that accept an optional <type>regconfig</>
8618     argument will use the configuration specified by
8619     <xref linkend="guc-default-text-search-config">
8620     when that argument is omitted.
8621    </para>
8622   </note>
8623
8624   <para>
8625    The functions in
8626    <xref linkend="textsearch-functions-debug-table">
8627    are listed separately because they are not usually used in everyday text
8628    searching operations.  They are helpful for development and debugging
8629    of new text search configurations.
8630   </para>
8631
8632     <table id="textsearch-functions-debug-table">
8633      <title>Text Search Debugging Functions</title>
8634      <tgroup cols="5">
8635       <thead>
8636        <row>
8637         <entry>Function</entry>
8638         <entry>Return Type</entry>
8639         <entry>Description</entry>
8640         <entry>Example</entry>
8641         <entry>Result</entry>
8642        </row>
8643       </thead>
8644       <tbody>
8645        <row>
8646         <entry>
8647          <indexterm>
8648           <primary>ts_debug</primary>
8649          </indexterm>
8650          <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>
8651         </entry>
8652         <entry><type>setof record</type></entry>
8653         <entry>test a configuration</entry>
8654         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
8655         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
8656        </row>
8657        <row>
8658         <entry>
8659          <indexterm>
8660           <primary>ts_lexize</primary>
8661          </indexterm>
8662          <literal><function>ts_lexize(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</function></literal>
8663         </entry>
8664         <entry><type>text[]</type></entry>
8665         <entry>test a dictionary</entry>
8666         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
8667         <entry><literal>{star}</literal></entry>
8668        </row>
8669        <row>
8670         <entry>
8671          <indexterm>
8672           <primary>ts_parse</primary>
8673          </indexterm>
8674          <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>
8675         </entry>
8676         <entry><type>setof record</type></entry>
8677         <entry>test a parser</entry>
8678         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
8679         <entry><literal>(1,foo) ...</literal></entry>
8680        </row>
8681        <row>
8682         <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>
8683         <entry><type>setof record</type></entry>
8684         <entry>test a parser</entry>
8685         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
8686         <entry><literal>(1,foo) ...</literal></entry>
8687        </row>
8688        <row>
8689         <entry>
8690          <indexterm>
8691           <primary>ts_token_type</primary>
8692          </indexterm>
8693          <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>
8694         </entry>
8695         <entry><type>setof record</type></entry>
8696         <entry>get token types defined by parser</entry>
8697         <entry><literal>ts_token_type('default')</literal></entry>
8698         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8699        </row>
8700        <row>
8701         <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>
8702         <entry><type>setof record</type></entry>
8703         <entry>get token types defined by parser</entry>
8704         <entry><literal>ts_token_type(3722)</literal></entry>
8705         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8706        </row>
8707        <row>
8708         <entry>
8709          <indexterm>
8710           <primary>ts_stat</primary>
8711          </indexterm>
8712          <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>
8713         </entry>
8714         <entry><type>setof record</type></entry>
8715         <entry>get statistics of a <type>tsvector</> column</entry>
8716         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
8717         <entry><literal>(foo,10,15) ...</literal></entry>
8718        </row>
8719       </tbody>
8720      </tgroup>
8721     </table>
8722
8723  </sect1>
8724
8725
8726  <sect1 id="functions-xml">
8727   <title>XML Functions</title>
8728
8729   <para>
8730    The functions and function-like expressions described in this
8731    section operate on values of type <type>xml</type>.  Check <xref
8732    linkend="datatype-xml"> for information about the <type>xml</type>
8733    type.  The function-like expressions <function>xmlparse</function>
8734    and <function>xmlserialize</function> for converting to and from
8735    type <type>xml</type> are not repeated here.  Use of most of these
8736    functions requires the installation to have been built
8737    with <command>configure --with-libxml</>.
8738   </para>
8739
8740   <sect2 id="functions-producing-xml">
8741    <title>Producing XML Content</title>
8742
8743    <para>
8744     A set of functions and function-like expressions are available for
8745     producing XML content from SQL data.  As such, they are
8746     particularly suitable for formatting query results into XML
8747     documents for processing in client applications.
8748    </para>
8749
8750    <sect3>
8751     <title><literal>xmlcomment</literal></title>
8752
8753     <indexterm>
8754      <primary>xmlcomment</primary>
8755     </indexterm>
8756
8757 <synopsis>
8758 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8759 </synopsis>
8760
8761     <para>
8762      The function <function>xmlcomment</function> creates an XML value
8763      containing an XML comment with the specified text as content.
8764      The text cannot contain <quote><literal>--</literal></quote> or end with a
8765      <quote><literal>-</literal></quote> so that the resulting construct is a valid
8766      XML comment.  If the argument is null, the result is null.
8767     </para>
8768
8769     <para>
8770      Example:
8771 <screen><![CDATA[
8772 SELECT xmlcomment('hello');
8773
8774   xmlcomment
8775 --------------
8776  <!--hello-->
8777 ]]></screen>
8778     </para>
8779    </sect3>
8780
8781    <sect3>
8782     <title><literal>xmlconcat</literal></title>
8783
8784     <indexterm>
8785      <primary>xmlconcat</primary>
8786     </indexterm>
8787
8788 <synopsis>
8789 <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8790 </synopsis>
8791
8792     <para>
8793      The function <function>xmlconcat</function> concatenates a list
8794      of individual XML values to create a single value containing an
8795      XML content fragment.  Null values are omitted; the result is
8796      only null if there are no nonnull arguments.
8797     </para>
8798
8799     <para>
8800      Example:
8801 <screen><![CDATA[
8802 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8803
8804       xmlconcat
8805 ----------------------
8806  <abc/><bar>foo</bar>
8807 ]]></screen>
8808     </para>
8809
8810     <para>
8811      XML declarations, if present, are combined as follows.  If all
8812      argument values have the same XML version declaration, that
8813      version is used in the result, else no version is used.  If all
8814      argument values have the standalone declaration value
8815      <quote>yes</quote>, then that value is used in the result.  If
8816      all argument values have a standalone declaration value and at
8817      least one is <quote>no</quote>, then that is used in the result.
8818      Else the result will have no standalone declaration.  If the
8819      result is determined to require a standalone declaration but no
8820      version declaration, a version declaration with version 1.0 will
8821      be used because XML requires an XML declaration to contain a
8822      version declaration.  Encoding declarations are ignored and
8823      removed in all cases.
8824     </para>
8825
8826     <para>
8827      Example:
8828 <screen><![CDATA[
8829 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
8830
8831              xmlconcat
8832 -----------------------------------
8833  <?xml version="1.1"?><foo/><bar/>
8834 ]]></screen>
8835     </para>
8836    </sect3>
8837
8838    <sect3>
8839     <title><literal>xmlelement</literal></title>
8840
8841    <indexterm>
8842     <primary>xmlelement</primary>
8843    </indexterm>
8844
8845 <synopsis>
8846 <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>)
8847 </synopsis>
8848
8849     <para>
8850      The <function>xmlelement</function> expression produces an XML
8851      element with the given name, attributes, and content.
8852     </para>
8853
8854     <para>
8855      Examples:
8856 <screen><![CDATA[
8857 SELECT xmlelement(name foo);
8858
8859  xmlelement
8860 ------------
8861  <foo/>
8862
8863 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8864
8865     xmlelement
8866 ------------------
8867  <foo bar="xyz"/>
8868
8869 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8870
8871              xmlelement
8872 -------------------------------------
8873  <foo bar="2007-01-26">content</foo>
8874 ]]></screen>
8875     </para>
8876
8877     <para>
8878      Element and attribute names that are not valid XML names are
8879      escaped by replacing the offending characters by the sequence
8880      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8881      <replaceable>HHHH</replaceable> is the character's Unicode
8882      codepoint in hexadecimal notation.  For example:
8883 <screen><![CDATA[
8884 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
8885
8886             xmlelement
8887 ----------------------------------
8888  <foo_x0024_bar a_x0026_b="xyz"/>
8889 ]]></screen>
8890     </para>
8891
8892     <para>
8893      An explicit attribute name need not be specified if the attribute
8894      value is a column reference, in which case the column's name will
8895      be used as the attribute name by default.  In other cases, the
8896      attribute must be given an explicit name.  So this example is
8897      valid:
8898 <screen>
8899 CREATE TABLE test (a xml, b xml);
8900 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8901 </screen>
8902      But these are not:
8903 <screen>
8904 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8905 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8906 </screen>
8907     </para>
8908
8909     <para>
8910      Element content, if specified, will be formatted according to
8911      its data type.  If the content is itself of type <type>xml</type>,
8912      complex XML documents can be constructed.  For example:
8913 <screen><![CDATA[
8914 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8915                             xmlelement(name abc),
8916                             xmlcomment('test'),
8917                             xmlelement(name xyz));
8918
8919                   xmlelement
8920 ----------------------------------------------
8921  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
8922 ]]></screen>
8923
8924      Content of other types will be formatted into valid XML character
8925      data.  This means in particular that the characters &lt;, &gt;,
8926      and &amp; will be converted to entities.  Binary data (data type
8927      <type>bytea</type>) will be represented in base64 or hex
8928      encoding, depending on the setting of the configuration parameter
8929      <xref linkend="guc-xmlbinary">.  The particular behavior for
8930      individual data types is expected to evolve in order to align the
8931      SQL and PostgreSQL data types with the XML Schema specification,
8932      at which point a more precise description will appear.
8933     </para>
8934    </sect3>
8935
8936    <sect3>
8937     <title><literal>xmlforest</literal></title>
8938
8939    <indexterm>
8940     <primary>xmlforest</primary>
8941    </indexterm>
8942
8943 <synopsis>
8944 <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8945 </synopsis>
8946
8947     <para>
8948      The <function>xmlforest</function> expression produces an XML
8949      forest (sequence) of elements using the given names and content.
8950     </para>
8951
8952     <para>
8953      Examples:
8954 <screen><![CDATA[
8955 SELECT xmlforest('abc' AS foo, 123 AS bar);
8956
8957           xmlforest
8958 ------------------------------
8959  <foo>abc</foo><bar>123</bar>
8960
8961
8962 SELECT xmlforest(table_name, column_name)
8963 FROM information_schema.columns
8964 WHERE table_schema = 'pg_catalog';
8965
8966                                          xmlforest
8967 -------------------------------------------------------------------------------------------
8968  <table_name>pg_authid</table_name><column_name>rolname</column_name>
8969  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8970  ...
8971 ]]></screen>
8972
8973      As seen in the second example, the element name can be omitted if
8974      the content value is a column reference, in which case the column
8975      name is used by default.  Otherwise, a name must be specified.
8976     </para>
8977
8978     <para>
8979      Element names that are not valid XML names are escaped as shown
8980      for <function>xmlelement</function> above.  Similarly, content
8981      data is escaped to make valid XML content, unless it is already
8982      of type <type>xml</type>.
8983     </para>
8984
8985     <para>
8986      Note that XML forests are not valid XML documents if they consist
8987      of more than one element, so it might be useful to wrap
8988      <function>xmlforest</function> expressions in
8989      <function>xmlelement</function>.
8990     </para>
8991    </sect3>
8992
8993    <sect3>
8994     <title><literal>xmlpi</literal></title>
8995
8996    <indexterm>
8997     <primary>xmlpi</primary>
8998    </indexterm>
8999
9000 <synopsis>
9001 <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
9002 </synopsis>
9003
9004     <para>
9005      The <function>xmlpi</function> expression creates an XML
9006      processing instruction.  The content, if present, must not
9007      contain the character sequence <literal>?&gt;</literal>.
9008     </para>
9009
9010     <para>
9011      Example:
9012 <screen><![CDATA[
9013 SELECT xmlpi(name php, 'echo "hello world";');
9014
9015             xmlpi
9016 -----------------------------
9017  <?php echo "hello world";?>
9018 ]]></screen>
9019     </para>
9020    </sect3>
9021
9022    <sect3>
9023     <title><literal>xmlroot</literal></title>
9024
9025    <indexterm>
9026     <primary>xmlroot</primary>
9027    </indexterm>
9028
9029 <synopsis>
9030 <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
9031 </synopsis>
9032
9033     <para>
9034      The <function>xmlroot</function> expression alters the properties
9035      of the root node of an XML value.  If a version is specified,
9036      it replaces the value in the root node's version declaration; if a
9037      standalone setting is specified, it replaces the value in the
9038      root node's standalone declaration.
9039     </para>
9040
9041     <para>
9042 <screen><![CDATA[
9043 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
9044                version '1.0', standalone yes);
9045
9046                 xmlroot
9047 ----------------------------------------
9048  <?xml version="1.0" standalone="yes"?>
9049  <content>abc</content>
9050 ]]></screen>
9051     </para>
9052    </sect3>
9053
9054    <sect3 id="functions-xml-xmlagg">
9055     <title><literal>xmlagg</literal></title>
9056
9057     <indexterm>
9058      <primary>xmlagg</primary>
9059     </indexterm>
9060
9061 <synopsis>
9062 <function>xmlagg</function>(<replaceable>xml</replaceable>)
9063 </synopsis>
9064
9065     <para>
9066      The function <function>xmlagg</function> is, unlike the other
9067      functions described here, an aggregate function.  It concatenates the
9068      input values to the aggregate function call,
9069      much like <function>xmlconcat</function> does, except that concatenation
9070      occurs across rows rather than across expressions in a single row.
9071      See <xref linkend="functions-aggregate"> for additional information
9072      about aggregate functions.
9073     </para>
9074
9075     <para>
9076      Example:
9077 <screen><![CDATA[
9078 CREATE TABLE test (y int, x xml);
9079 INSERT INTO test VALUES (1, '<foo>abc</foo>');
9080 INSERT INTO test VALUES (2, '<bar/>');
9081 SELECT xmlagg(x) FROM test;
9082         xmlagg
9083 ----------------------
9084  <foo>abc</foo><bar/>
9085 ]]></screen>
9086     </para>
9087
9088     <para>
9089      To determine the order of the concatenation, an <literal>ORDER BY</>
9090      clause may be added to the aggregate call as described in
9091      <xref linkend="syntax-aggregates">. For example:
9092
9093 <screen><![CDATA[
9094 SELECT xmlagg(x ORDER BY y DESC) FROM test;
9095         xmlagg
9096 ----------------------
9097  <bar/><foo>abc</foo>
9098 ]]></screen>
9099     </para>
9100
9101     <para>
9102      The following non-standard approach used to be recommended
9103      in previous versions, and may still be useful in specific
9104      cases:
9105
9106 <screen><![CDATA[
9107 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
9108         xmlagg
9109 ----------------------
9110  <bar/><foo>abc</foo>
9111 ]]></screen>
9112     </para>
9113    </sect3>
9114    </sect2>
9115
9116    <sect2 id="functions-xml-predicates">
9117     <title>XML Predicates</title>
9118
9119     <para>
9120      The expressions described in this section check properties
9121      of <type>xml</type> values.
9122     </para>
9123
9124    <sect3>
9125     <title><literal>IS DOCUMENT</literal></title>
9126
9127     <indexterm>
9128      <primary>IS DOCUMENT</primary>
9129     </indexterm>
9130
9131 <synopsis>
9132 <replaceable>xml</replaceable> IS DOCUMENT
9133 </synopsis>
9134
9135     <para>
9136      The expression <literal>IS DOCUMENT</literal> returns true if the
9137      argument XML value is a proper XML document, false if it is not
9138      (that is, it is a content fragment), or null if the argument is
9139      null.  See <xref linkend="datatype-xml"> about the difference
9140      between documents and content fragments.
9141     </para>
9142    </sect3>
9143
9144    <sect3 id="xml-exists">
9145     <title><literal>XMLEXISTS</literal></title>
9146
9147     <indexterm>
9148      <primary>XMLEXISTS</primary>
9149     </indexterm>
9150
9151 <synopsis>
9152 <function>XMLEXISTS</function>(<replaceable>text</replaceable> PASSING <optional>BY REF</optional> <replaceable>xml</replaceable> <optional>BY REF</optional>)
9153 </synopsis>
9154
9155     <para>
9156      The function <function>xmlexists</function> returns true if the
9157      XPath expression in the first argument returns any nodes, and
9158      false otherwise.  (If either argument is null, the result is
9159      null.)
9160     </para>
9161
9162     <para>
9163      Example:
9164      <screen><![CDATA[
9165 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY REF '<towns><town>Toronto</town><town>Ottawa</town></towns>');
9166
9167  xmlexists
9168 ------------
9169  t
9170 (1 row)
9171 ]]></screen>
9172     </para>
9173
9174     <para>
9175      The <literal>BY REF</literal> clauses have no effect in
9176      PostgreSQL, but are allowed for SQL conformance and compatibility
9177      with other implementations.  Per SQL standard, the
9178      first <literal>BY REF</literal> is required, the second is
9179      optional.  Also note that the SQL standard specifies
9180      the <function>xmlexists</function> construct to take an XQuery
9181      expression as first argument, but PostgreSQL currently only
9182      supports XPath, which is a subset of XQuery.
9183     </para>
9184    </sect3>
9185
9186    <sect3 id="xml-is-well-formed">
9187     <title><literal>xml_is_well_formed</literal></title>
9188
9189     <indexterm>
9190      <primary>xml_is_well_formed</primary>
9191     </indexterm>
9192
9193     <indexterm>
9194      <primary>xml_is_well_formed_document</primary>
9195     </indexterm>
9196
9197     <indexterm>
9198      <primary>xml_is_well_formed_content</primary>
9199     </indexterm>
9200
9201 <synopsis>
9202 <function>xml_is_well_formed</function>(<replaceable>text</replaceable>)
9203 <function>xml_is_well_formed_document</function>(<replaceable>text</replaceable>)
9204 <function>xml_is_well_formed_content</function>(<replaceable>text</replaceable>)
9205 </synopsis>
9206
9207     <para>
9208      These functions check whether a <type>text</> string is well-formed XML,
9209      returning a Boolean result.
9210      <function>xml_is_well_formed_document</function> checks for a well-formed
9211      document, while <function>xml_is_well_formed_content</function> checks
9212      for well-formed content.  <function>xml_is_well_formed</function> does
9213      the former if the <xref linkend="guc-xmloption"> configuration
9214      parameter is set to <literal>DOCUMENT</>, or the latter if it is set to
9215      <literal>CONTENT</>.  This means that
9216      <function>xml_is_well_formed</function> is useful for seeing whether
9217      a simple cast to type <type>xml</> will succeed, whereas the other two
9218      functions are useful for seeing whether the corresponding variants of
9219      <function>XMLPARSE</> will succeed.
9220     </para>
9221
9222     <para>
9223      Examples:
9224
9225 <screen><![CDATA[
9226 SET xmloption TO DOCUMENT;
9227 SELECT xml_is_well_formed('<>');
9228  xml_is_well_formed 
9229 --------------------
9230  f
9231 (1 row)
9232
9233 SELECT xml_is_well_formed('<abc/>');
9234  xml_is_well_formed 
9235 --------------------
9236  t
9237 (1 row)
9238
9239 SET xmloption TO CONTENT;
9240 SELECT xml_is_well_formed('abc');
9241  xml_is_well_formed 
9242 --------------------
9243  t
9244 (1 row)
9245
9246 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
9247  xml_is_well_formed_document 
9248 -----------------------------
9249  t
9250 (1 row)
9251
9252 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
9253  xml_is_well_formed_document 
9254 -----------------------------
9255  f
9256 (1 row)
9257 ]]></screen>
9258
9259      The last example shows that the checks include whether
9260      namespaces are correctly matched.
9261     </para>
9262    </sect3>
9263   </sect2>
9264
9265   <sect2 id="functions-xml-processing">
9266    <title>Processing XML</title>
9267
9268    <indexterm>
9269     <primary>XPath</primary>
9270    </indexterm>
9271
9272    <para>
9273     To process values of data type <type>xml</type>, PostgreSQL offers
9274     the functions <function>xpath</function> and
9275     <function>xpath_exists</function>, which evaluate XPath 1.0
9276     expressions.
9277    </para>
9278
9279 <synopsis>
9280 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9281 </synopsis>
9282
9283    <para>
9284     The function <function>xpath</function> evaluates the XPath
9285     expression <replaceable>xpath</replaceable> (a <type>text</> value)
9286     against the XML value
9287     <replaceable>xml</replaceable>.  It returns an array of XML values
9288     corresponding to the node set produced by the XPath expression.
9289     If the XPath expression returns a scalar value rather than a node set,
9290     a single-element array is returned.
9291    </para>
9292
9293   <para>
9294     The second argument must be a well formed XML document. In particular,
9295     it must have a single root node element.
9296   </para>
9297
9298    <para>
9299     The optional third argument of the function is an array of namespace
9300     mappings.  This array should be a two-dimensional <type>text</> array with
9301     the length of the second axis being equal to 2 (i.e., it should be an
9302     array of arrays, each of which consists of exactly 2 elements).
9303     The first element of each array entry is the namespace name (alias), the
9304     second the namespace URI. It is not required that aliases provided in
9305     this array be the same as those being used in the XML document itself (in
9306     other words, both in the XML document and in the <function>xpath</function>
9307     function context, aliases are <emphasis>local</>).
9308    </para>
9309
9310    <para>
9311     Example:
9312 <screen><![CDATA[
9313 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9314              ARRAY[ARRAY['my', 'http://example.com']]);
9315
9316  xpath  
9317 --------
9318  {test}
9319 (1 row)
9320 ]]></screen>
9321    </para>
9322
9323    <para>
9324     To deal with default (anonymous) namespaces, do something like this:
9325 <screen><![CDATA[
9326 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
9327              ARRAY[ARRAY['mydefns', 'http://example.com']]);
9328
9329  xpath
9330 --------
9331  {test}
9332 (1 row)
9333 ]]></screen>
9334    </para>
9335
9336    <indexterm>
9337     <primary>xpath_exists</primary>
9338    </indexterm>
9339
9340 <synopsis>
9341 <function>xpath_exists</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9342 </synopsis>
9343
9344    <para>
9345     The function <function>xpath_exists</function> is a specialized form
9346     of the <function>xpath</function> function.  Instead of returning the
9347     individual XML values that satisfy the XPath, this function returns a
9348     Boolean indicating whether the query was satisfied or not.  This
9349     function is equivalent to the standard <literal>XMLEXISTS</> predicate,
9350     except that it also offers support for a namespace mapping argument.
9351    </para>
9352
9353    <para>
9354     Example:
9355 <screen><![CDATA[
9356 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9357                      ARRAY[ARRAY['my', 'http://example.com']]);
9358
9359  xpath_exists  
9360 --------------
9361  t
9362 (1 row)
9363 ]]></screen>
9364    </para>
9365   </sect2>
9366
9367   <sect2 id="functions-xml-mapping">
9368    <title>Mapping Tables to XML</title>
9369
9370    <indexterm zone="functions-xml-mapping">
9371     <primary>XML export</primary>
9372    </indexterm>
9373
9374    <para>
9375     The following functions map the contents of relational tables to
9376     XML values.  They can be thought of as XML export functionality:
9377 <synopsis>
9378 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9379 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
9380 cursor_to_xml(cursor refcursor, count int, nulls boolean,
9381               tableforest boolean, targetns text)
9382 </synopsis>
9383     The return type of each function is <type>xml</type>.
9384    </para>
9385
9386    <para>
9387     <function>table_to_xml</function> maps the content of the named
9388     table, passed as parameter <parameter>tbl</parameter>.  The
9389     <type>regclass</type> type accepts strings identifying tables using the
9390     usual notation, including optional schema qualifications and
9391     double quotes.  <function>query_to_xml</function> executes the
9392     query whose text is passed as parameter
9393     <parameter>query</parameter> and maps the result set.
9394     <function>cursor_to_xml</function> fetches the indicated number of
9395     rows from the cursor specified by the parameter
9396     <parameter>cursor</parameter>.  This variant is recommended if
9397     large tables have to be mapped, because the result value is built
9398     up in memory by each function.
9399    </para>
9400
9401    <para>
9402     If <parameter>tableforest</parameter> is false, then the resulting
9403     XML document looks like this:
9404 <screen><![CDATA[
9405 <tablename>
9406   <row>
9407     <columnname1>data</columnname1>
9408     <columnname2>data</columnname2>
9409   </row>
9410
9411   <row>
9412     ...
9413   </row>
9414
9415   ...
9416 </tablename>
9417 ]]></screen>
9418
9419     If <parameter>tableforest</parameter> is true, the result is an
9420     XML content fragment that looks like this:
9421 <screen><![CDATA[
9422 <tablename>
9423   <columnname1>data</columnname1>
9424   <columnname2>data</columnname2>
9425 </tablename>
9426
9427 <tablename>
9428   ...
9429 </tablename>
9430
9431 ...
9432 ]]></screen>
9433
9434     If no table name is available, that is, when mapping a query or a
9435     cursor, the string <literal>table</literal> is used in the first
9436     format, <literal>row</literal> in the second format.
9437    </para>
9438
9439    <para>
9440     The choice between these formats is up to the user.  The first
9441     format is a proper XML document, which will be important in many
9442     applications.  The second format tends to be more useful in the
9443     <function>cursor_to_xml</function> function if the result values are to be
9444     reassembled into one document later on.  The functions for
9445     producing XML content discussed above, in particular
9446     <function>xmlelement</function>, can be used to alter the results
9447     to taste.
9448    </para>
9449
9450    <para>
9451     The data values are mapped in the same way as described for the
9452     function <function>xmlelement</function> above.
9453    </para>
9454
9455    <para>
9456     The parameter <parameter>nulls</parameter> determines whether null
9457     values should be included in the output.  If true, null values in
9458     columns are represented as:
9459 <screen><![CDATA[
9460 <columnname xsi:nil="true"/>
9461 ]]></screen>
9462     where <literal>xsi</literal> is the XML namespace prefix for XML
9463     Schema Instance.  An appropriate namespace declaration will be
9464     added to the result value.  If false, columns containing null
9465     values are simply omitted from the output.
9466    </para>
9467
9468    <para>
9469     The parameter <parameter>targetns</parameter> specifies the
9470     desired XML namespace of the result.  If no particular namespace
9471     is wanted, an empty string should be passed.
9472    </para>
9473
9474    <para>
9475     The following functions return XML Schema documents describing the
9476     mappings performed by the corresponding functions above:
9477 <synopsis>
9478 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9479 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9480 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
9481 </synopsis>
9482     It is essential that the same parameters are passed in order to
9483     obtain matching XML data mappings and XML Schema documents.
9484    </para>
9485
9486    <para>
9487     The following functions produce XML data mappings and the
9488     corresponding XML Schema in one document (or forest), linked
9489     together.  They can be useful where self-contained and
9490     self-describing results are wanted:
9491 <synopsis>
9492 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9493 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9494 </synopsis>
9495    </para>
9496
9497    <para>
9498     In addition, the following functions are available to produce
9499     analogous mappings of entire schemas or the entire current
9500     database:
9501 <synopsis>
9502 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
9503 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9504 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9505
9506 database_to_xml(nulls boolean, tableforest boolean, targetns text)
9507 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
9508 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
9509 </synopsis>
9510
9511     Note that these potentially produce a lot of data, which needs to
9512     be built up in memory.  When requesting content mappings of large
9513     schemas or databases, it might be worthwhile to consider mapping the
9514     tables separately instead, possibly even through a cursor.
9515    </para>
9516
9517    <para>
9518     The result of a schema content mapping looks like this:
9519
9520 <screen><![CDATA[
9521 <schemaname>
9522
9523 table1-mapping
9524
9525 table2-mapping
9526
9527 ...
9528
9529 </schemaname>]]></screen>
9530
9531     where the format of a table mapping depends on the
9532     <parameter>tableforest</parameter> parameter as explained above.
9533    </para>
9534
9535    <para>
9536     The result of a database content mapping looks like this:
9537
9538 <screen><![CDATA[
9539 <dbname>
9540
9541 <schema1name>
9542   ...
9543 </schema1name>
9544
9545 <schema2name>
9546   ...
9547 </schema2name>
9548
9549 ...
9550
9551 </dbname>]]></screen>
9552
9553     where the schema mapping is as above.
9554    </para>
9555
9556    <para>
9557     As an example of using the output produced by these functions,
9558     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
9559     converts the output of
9560     <function>table_to_xml_and_xmlschema</function> to an HTML
9561     document containing a tabular rendition of the table data.  In a
9562     similar manner, the results from these functions can be
9563     converted into other XML-based formats.
9564    </para>
9565
9566    <figure id="xslt-xml-html">
9567     <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
9568 <programlisting><![CDATA[
9569 <?xml version="1.0"?>
9570 <xsl:stylesheet version="1.0"
9571     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
9572     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
9573     xmlns="http://www.w3.org/1999/xhtml"
9574 >
9575
9576   <xsl:output method="xml"
9577       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
9578       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
9579       indent="yes"/>
9580
9581   <xsl:template match="/*">
9582     <xsl:variable name="schema" select="//xsd:schema"/>
9583     <xsl:variable name="tabletypename"
9584                   select="$schema/xsd:element[@name=name(current())]/@type"/>
9585     <xsl:variable name="rowtypename"
9586                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
9587
9588     <html>
9589       <head>
9590         <title><xsl:value-of select="name(current())"/></title>
9591       </head>
9592       <body>
9593         <table>
9594           <tr>
9595             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
9596               <th><xsl:value-of select="."/></th>
9597             </xsl:for-each>
9598           </tr>
9599
9600           <xsl:for-each select="row">
9601             <tr>
9602               <xsl:for-each select="*">
9603                 <td><xsl:value-of select="."/></td>
9604               </xsl:for-each>
9605             </tr>
9606           </xsl:for-each>
9607         </table>
9608       </body>
9609     </html>
9610   </xsl:template>
9611
9612 </xsl:stylesheet>
9613 ]]></programlisting>
9614    </figure>
9615   </sect2>
9616  </sect1>
9617
9618
9619  <sect1 id="functions-sequence">
9620   <title>Sequence Manipulation Functions</title>
9621
9622   <indexterm>
9623    <primary>sequence</primary>
9624   </indexterm>
9625   <indexterm>
9626    <primary>nextval</primary>
9627   </indexterm>
9628   <indexterm>
9629    <primary>currval</primary>
9630   </indexterm>
9631   <indexterm>
9632    <primary>lastval</primary>
9633   </indexterm>
9634   <indexterm>
9635    <primary>setval</primary>
9636   </indexterm>
9637
9638   <para>
9639    This section describes <productname>PostgreSQL</productname>'s
9640    functions for operating on <firstterm>sequence objects</firstterm>.
9641    Sequence objects (also called sequence generators or just
9642    sequences) are special single-row tables created with <xref
9643    linkend="sql-createsequence">.
9644    A sequence object is usually used to generate unique identifiers
9645    for rows of a table.  The sequence functions, listed in <xref
9646    linkend="functions-sequence-table">, provide simple, multiuser-safe
9647    methods for obtaining successive sequence values from sequence
9648    objects.
9649   </para>
9650
9651    <table id="functions-sequence-table">
9652     <title>Sequence Functions</title>
9653     <tgroup cols="3">
9654      <thead>
9655       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
9656      </thead>
9657
9658      <tbody>
9659       <row>
9660         <entry><literal><function>currval(<type>regclass</type>)</function></literal></entry>
9661         <entry><type>bigint</type></entry>
9662         <entry>Return value most recently obtained with
9663         <function>nextval</function> for specified sequence</entry>
9664       </row>
9665       <row>
9666         <entry><literal><function>lastval()</function></literal></entry>
9667         <entry><type>bigint</type></entry>
9668         <entry>Return value most recently obtained with
9669         <function>nextval</function> for any sequence</entry>
9670       </row>
9671       <row>
9672         <entry><literal><function>nextval(<type>regclass</type>)</function></literal></entry>
9673         <entry><type>bigint</type></entry>
9674         <entry>Advance sequence and return new value</entry>
9675       </row>
9676       <row>
9677         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>)</function></literal></entry>
9678         <entry><type>bigint</type></entry>
9679         <entry>Set sequence's current value</entry>
9680       </row>
9681       <row>
9682         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</function></literal></entry>
9683         <entry><type>bigint</type></entry>
9684         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
9685       </row>
9686      </tbody>
9687     </tgroup>
9688    </table>
9689
9690   <para>
9691    The sequence to be operated on by a sequence function is specified by
9692    a <type>regclass</> argument, which is simply the OID of the sequence in the
9693    <structname>pg_class</> system catalog.  You do not have to look up the
9694    OID by hand, however, since the <type>regclass</> data type's input
9695    converter will do the work for you.  Just write the sequence name enclosed
9696    in single quotes so that it looks like a literal constant.  For
9697    compatibility with the handling of ordinary
9698    <acronym>SQL</acronym> names, the string will be converted to lower case
9699    unless it contains double quotes around the sequence name.  Thus:
9700 <programlisting>
9701 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
9702 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
9703 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
9704 </programlisting>
9705    The sequence name can be schema-qualified if necessary:
9706 <programlisting>
9707 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
9708 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
9709 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
9710 </programlisting>
9711    See <xref linkend="datatype-oid"> for more information about
9712    <type>regclass</>.
9713   </para>
9714
9715   <note>
9716    <para>
9717     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
9718     sequence functions were of type <type>text</>, not <type>regclass</>, and
9719     the above-described conversion from a text string to an OID value would
9720     happen at run time during each call.  For backward compatibility, this
9721     facility still exists, but internally it is now handled as an implicit
9722     coercion from <type>text</> to <type>regclass</> before the function is
9723     invoked.
9724    </para>
9725
9726    <para>
9727     When you write the argument of a sequence function as an unadorned
9728     literal string, it becomes a constant of type <type>regclass</>.
9729     Since this is really just an OID, it will track the originally
9730     identified sequence despite later renaming, schema reassignment,
9731     etc.  This <quote>early binding</> behavior is usually desirable for
9732     sequence references in column defaults and views.  But sometimes you might
9733     want <quote>late binding</> where the sequence reference is resolved
9734     at run time.  To get late-binding behavior, force the constant to be
9735     stored as a <type>text</> constant instead of <type>regclass</>:
9736 <programlisting>
9737 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
9738 </programlisting>
9739     Note that late binding was the only behavior supported in
9740     <productname>PostgreSQL</productname> releases before 8.1, so you
9741     might need to do this to preserve the semantics of old applications.
9742    </para>
9743
9744    <para>
9745     Of course, the argument of a sequence function can be an expression
9746     as well as a constant.  If it is a text expression then the implicit
9747     coercion will result in a run-time lookup.
9748    </para>
9749   </note>
9750
9751   <para>
9752    The available sequence functions are:
9753
9754     <variablelist>
9755      <varlistentry>
9756       <term><function>nextval</function></term>
9757       <listitem>
9758        <para>
9759         Advance the sequence object to its next value and return that
9760         value.  This is done atomically: even if multiple sessions
9761         execute <function>nextval</function> concurrently, each will safely receive
9762         a distinct sequence value.
9763        </para>
9764       </listitem>
9765      </varlistentry>
9766
9767      <varlistentry>
9768       <term><function>currval</function></term>
9769       <listitem>
9770        <para>
9771         Return the value most recently obtained by <function>nextval</function>
9772         for this sequence in the current session.  (An error is
9773         reported if <function>nextval</function> has never been called for this
9774         sequence in this session.)  Because this is returning
9775         a session-local value, it gives a predictable answer whether or not
9776         other sessions have executed <function>nextval</function> since the
9777         current session did.
9778        </para>
9779       </listitem>
9780      </varlistentry>
9781
9782      <varlistentry>
9783       <term><function>lastval</function></term>
9784       <listitem>
9785        <para>
9786         Return the value most recently returned by
9787         <function>nextval</> in the current session. This function is
9788         identical to <function>currval</function>, except that instead
9789         of taking the sequence name as an argument it fetches the
9790         value of the last sequence used by <function>nextval</function>
9791         in the current session. It is an error to call
9792         <function>lastval</function> if <function>nextval</function>
9793         has not yet been called in the current session.
9794        </para>
9795       </listitem>
9796      </varlistentry>
9797
9798      <varlistentry>
9799       <term><function>setval</function></term>
9800       <listitem>
9801        <para>
9802         Reset the sequence object's counter value.  The two-parameter
9803         form sets the sequence's <literal>last_value</literal> field to the
9804         specified value and sets its <literal>is_called</literal> field to
9805         <literal>true</literal>, meaning that the next
9806         <function>nextval</function> will advance the sequence before
9807         returning a value.  The value reported by <function>currval</> is
9808         also set to the specified value.  In the three-parameter form,
9809         <literal>is_called</literal> can be set to either <literal>true</literal>
9810         or <literal>false</literal>.  <literal>true</> has the same effect as
9811         the two-parameter form. If it is set to <literal>false</literal>, the
9812         next <function>nextval</function> will return exactly the specified
9813         value, and sequence advancement commences with the following
9814         <function>nextval</function>.  Furthermore, the value reported by
9815         <function>currval</> is not changed in this case (this is a change
9816         from pre-8.3 behavior).  For example,
9817
9818 <screen>
9819 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
9820 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
9821 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
9822 </screen>
9823
9824         The result returned by <function>setval</function> is just the value of its
9825         second argument.
9826        </para>
9827       </listitem>
9828      </varlistentry>
9829     </variablelist>
9830   </para>
9831
9832   <para>
9833    If a sequence object has been created with default parameters,
9834    successive <function>nextval</function> calls will return successive values
9835    beginning with 1.  Other behaviors can be obtained by using
9836    special parameters in the <xref linkend="sql-createsequence"> command;
9837    see its command reference page for more information.
9838   </para>
9839
9840   <important>
9841    <para>
9842     To avoid blocking concurrent transactions that obtain numbers from the
9843     same sequence, a <function>nextval</function> operation is never rolled back;
9844     that is, once a value has been fetched it is considered used, even if the
9845     transaction that did the <function>nextval</function> later aborts.  This means
9846     that aborted transactions might leave unused <quote>holes</quote> in the
9847     sequence of assigned values.  <function>setval</function> operations are never
9848     rolled back, either.
9849    </para>
9850   </important>
9851
9852  </sect1>
9853
9854
9855  <sect1 id="functions-conditional">
9856   <title>Conditional Expressions</title>
9857
9858   <indexterm>
9859    <primary>CASE</primary>
9860   </indexterm>
9861
9862   <indexterm>
9863    <primary>conditional expression</primary>
9864   </indexterm>
9865
9866   <para>
9867    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
9868    available in <productname>PostgreSQL</productname>.
9869   </para>
9870
9871   <tip>
9872    <para>
9873     If your needs go beyond the capabilities of these conditional
9874     expressions, you might want to consider writing a stored procedure
9875     in a more expressive programming language.
9876    </para>
9877   </tip>
9878
9879   <sect2 id="functions-case">
9880    <title><literal>CASE</></title>
9881
9882   <para>
9883    The <acronym>SQL</acronym> <token>CASE</token> expression is a
9884    generic conditional expression, similar to if/else statements in
9885    other programming languages:
9886
9887 <synopsis>
9888 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
9889      <optional>WHEN ...</optional>
9890      <optional>ELSE <replaceable>result</replaceable></optional>
9891 END
9892 </synopsis>
9893
9894    <token>CASE</token> clauses can be used wherever
9895    an expression is valid.  Each <replaceable>condition</replaceable> is an
9896    expression that returns a <type>boolean</type> result.  If the condition's
9897    result is true, the value of the <token>CASE</token> expression is the
9898    <replaceable>result</replaceable> that follows the condition, and the
9899    remainder of the <token>CASE</token> expression is not processed.  If the
9900    condition's result is not true, any subsequent <token>WHEN</token> clauses
9901    are examined in the same manner.  If no <token>WHEN</token>
9902    <replaceable>condition</replaceable> yields true, the value of the
9903    <token>CASE</> expression is the <replaceable>result</replaceable> of the
9904    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
9905    omitted and no condition is true, the result is null.
9906   </para>
9907
9908    <para>
9909     An example:
9910 <screen>
9911 SELECT * FROM test;
9912
9913  a
9914 ---
9915  1
9916  2
9917  3
9918
9919
9920 SELECT a,
9921        CASE WHEN a=1 THEN 'one'
9922             WHEN a=2 THEN 'two'
9923             ELSE 'other'
9924        END
9925     FROM test;
9926
9927  a | case
9928 ---+-------
9929  1 | one
9930  2 | two
9931  3 | other
9932 </screen>
9933    </para>
9934
9935   <para>
9936    The data types of all the <replaceable>result</replaceable>
9937    expressions must be convertible to a single output type.
9938    See <xref linkend="typeconv-union-case"> for more details.
9939   </para>
9940
9941   <para>
9942    There is a <quote>simple</> form of <token>CASE</token> expression
9943    that is a variant of the general form above:
9944
9945 <synopsis>
9946 CASE <replaceable>expression</replaceable>
9947     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
9948     <optional>WHEN ...</optional>
9949     <optional>ELSE <replaceable>result</replaceable></optional>
9950 END
9951 </synopsis>
9952
9953    The first
9954    <replaceable>expression</replaceable> is computed, then compared to
9955    each of the <replaceable>value</replaceable> expressions in the
9956    <token>WHEN</token> clauses until one is found that is equal to it.  If
9957    no match is found, the <replaceable>result</replaceable> of the
9958    <token>ELSE</token> clause (or a null value) is returned.  This is similar
9959    to the <function>switch</function> statement in C.
9960   </para>
9961
9962    <para>
9963     The example above can be written using the simple
9964     <token>CASE</token> syntax:
9965 <screen>
9966 SELECT a,
9967        CASE a WHEN 1 THEN 'one'
9968               WHEN 2 THEN 'two'
9969               ELSE 'other'
9970        END
9971     FROM test;
9972
9973  a | case
9974 ---+-------
9975  1 | one
9976  2 | two
9977  3 | other
9978 </screen>
9979    </para>
9980
9981    <para>
9982     A <token>CASE</token> expression does not evaluate any subexpressions
9983     that are not needed to determine the result.  For example, this is a
9984     possible way of avoiding a division-by-zero failure:
9985 <programlisting>
9986 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
9987 </programlisting>
9988    </para>
9989   </sect2>
9990
9991   <sect2 id="functions-coalesce-nvl-ifnull">
9992    <title><literal>COALESCE</></title>
9993
9994   <indexterm>
9995    <primary>COALESCE</primary>
9996   </indexterm>
9997
9998   <indexterm>
9999    <primary>NVL</primary>
10000   </indexterm>
10001
10002   <indexterm>
10003    <primary>IFNULL</primary>
10004   </indexterm>
10005
10006 <synopsis>
10007 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10008 </synopsis>
10009
10010   <para>
10011    The <function>COALESCE</function> function returns the first of its
10012    arguments that is not null.  Null is returned only if all arguments
10013    are null.  It is often used to substitute a default value for
10014    null values when data is retrieved for display, for example:
10015 <programlisting>
10016 SELECT COALESCE(description, short_description, '(none)') ...
10017 </programlisting>
10018    This returns <varname>description</> if it is not null, otherwise
10019    <varname>short_description</> if it is not null, otherwise <literal>(none)</>.
10020   </para>
10021
10022    <para>
10023     Like a <token>CASE</token> expression, <function>COALESCE</function> only
10024     evaluates the arguments that are needed to determine the result;
10025     that is, arguments to the right of the first non-null argument are
10026     not evaluated.  This SQL-standard function provides capabilities similar
10027     to <function>NVL</> and <function>IFNULL</>, which are used in some other
10028     database systems.
10029    </para>
10030   </sect2>
10031
10032   <sect2 id="functions-nullif">
10033    <title><literal>NULLIF</></title>
10034
10035   <indexterm>
10036    <primary>NULLIF</primary>
10037   </indexterm>
10038
10039 <synopsis>
10040 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
10041 </synopsis>
10042
10043   <para>
10044    The <function>NULLIF</function> function returns a null value if
10045    <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
10046    otherwise it returns <replaceable>value1</replaceable>.
10047    This can be used to perform the inverse operation of the
10048    <function>COALESCE</function> example given above:
10049 <programlisting>
10050 SELECT NULLIF(value, '(none)') ...
10051 </programlisting>
10052   </para>
10053   <para>
10054    In this example, if <literal>value</literal> is <literal>(none)</>,
10055    null is returned, otherwise the value of <literal>value</literal>
10056    is returned.
10057   </para>
10058
10059   </sect2>
10060
10061   <sect2 id="functions-greatest-least">
10062    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
10063
10064   <indexterm>
10065    <primary>GREATEST</primary>
10066   </indexterm>
10067   <indexterm>
10068    <primary>LEAST</primary>
10069   </indexterm>
10070
10071 <synopsis>
10072 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10073 </synopsis>
10074 <synopsis>
10075 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10076 </synopsis>
10077
10078    <para>
10079     The <function>GREATEST</> and <function>LEAST</> functions select the
10080     largest or smallest value from a list of any number of expressions.
10081     The expressions must all be convertible to a common data type, which
10082     will be the type of the result
10083     (see <xref linkend="typeconv-union-case"> for details).  NULL values
10084     in the list are ignored.  The result will be NULL only if all the
10085     expressions evaluate to NULL.
10086    </para>
10087
10088    <para>
10089     Note that <function>GREATEST</> and <function>LEAST</> are not in
10090     the SQL standard, but are a common extension.  Some other databases
10091     make them return NULL if any argument is NULL, rather than only when
10092     all are NULL.
10093    </para>
10094   </sect2>
10095  </sect1>
10096
10097  <sect1 id="functions-array">
10098   <title>Array Functions and Operators</title>
10099
10100   <para>
10101    <xref linkend="array-operators-table"> shows the operators
10102    available for array types.
10103   </para>
10104
10105     <table id="array-operators-table">
10106      <title>Array Operators</title>
10107      <tgroup cols="4">
10108       <thead>
10109        <row>
10110         <entry>Operator</entry>
10111         <entry>Description</entry>
10112         <entry>Example</entry>
10113         <entry>Result</entry>
10114        </row>
10115       </thead>
10116       <tbody>
10117        <row>
10118         <entry> <literal>=</literal> </entry>
10119         <entry>equal</entry>
10120         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
10121         <entry><literal>t</literal></entry>
10122        </row>
10123
10124        <row>
10125         <entry> <literal>&lt;&gt;</literal> </entry>
10126         <entry>not equal</entry>
10127         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
10128         <entry><literal>t</literal></entry>
10129        </row>
10130
10131        <row>
10132         <entry> <literal>&lt;</literal> </entry>
10133         <entry>less than</entry>
10134         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
10135         <entry><literal>t</literal></entry>
10136        </row>
10137
10138        <row>
10139         <entry> <literal>&gt;</literal> </entry>
10140         <entry>greater than</entry>
10141         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
10142         <entry><literal>t</literal></entry>
10143        </row>
10144
10145        <row>
10146         <entry> <literal>&lt;=</literal> </entry>
10147         <entry>less than or equal</entry>
10148         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
10149         <entry><literal>t</literal></entry>
10150        </row>
10151
10152        <row>
10153         <entry> <literal>&gt;=</literal> </entry>
10154         <entry>greater than or equal</entry>
10155         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
10156         <entry><literal>t</literal></entry>
10157        </row>
10158
10159        <row>
10160         <entry> <literal>@&gt;</literal> </entry>
10161         <entry>contains</entry>
10162         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
10163         <entry><literal>t</literal></entry>
10164        </row>
10165
10166        <row>
10167         <entry> <literal>&lt;@</literal> </entry>
10168         <entry>is contained by</entry>
10169         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
10170         <entry><literal>t</literal></entry>
10171        </row>
10172
10173        <row>
10174         <entry> <literal>&amp;&amp;</literal> </entry>
10175         <entry>overlap (have elements in common)</entry>
10176         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
10177         <entry><literal>t</literal></entry>
10178        </row>
10179
10180        <row>
10181         <entry> <literal>||</literal> </entry>
10182         <entry>array-to-array concatenation</entry>
10183         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
10184         <entry><literal>{1,2,3,4,5,6}</literal></entry>
10185        </row>
10186
10187        <row>
10188         <entry> <literal>||</literal> </entry>
10189         <entry>array-to-array concatenation</entry>
10190         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
10191         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
10192        </row>
10193
10194        <row>
10195         <entry> <literal>||</literal> </entry>
10196         <entry>element-to-array concatenation</entry>
10197         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
10198         <entry><literal>{3,4,5,6}</literal></entry>
10199        </row>
10200
10201        <row>
10202         <entry> <literal>||</literal> </entry>
10203         <entry>array-to-element concatenation</entry>
10204         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
10205         <entry><literal>{4,5,6,7}</literal></entry>
10206        </row>
10207       </tbody>
10208      </tgroup>
10209     </table>
10210
10211   <para>
10212    Array comparisons compare the array contents element-by-element,
10213    using the default B-tree comparison function for the element data type.
10214    In multidimensional arrays the elements are visited in row-major order
10215    (last subscript varies most rapidly).
10216    If the contents of two arrays are equal but the dimensionality is
10217    different, the first difference in the dimensionality information
10218    determines the sort order.  (This is a change from versions of
10219    <productname>PostgreSQL</> prior to 8.2: older versions would claim
10220    that two arrays with the same contents were equal, even if the
10221    number of dimensions or subscript ranges were different.)
10222   </para>
10223
10224   <para>
10225    See <xref linkend="arrays"> for more details about array operator
10226    behavior.
10227   </para>
10228
10229   <para>
10230    <xref linkend="array-functions-table"> shows the functions
10231    available for use with array types. See <xref linkend="arrays">
10232    for more information  and examples of the use of these functions.
10233   </para>
10234
10235   <indexterm>
10236     <primary>array_append</primary>
10237   </indexterm>
10238   <indexterm>
10239     <primary>array_cat</primary>
10240   </indexterm>
10241   <indexterm>
10242     <primary>array_ndims</primary>
10243   </indexterm>
10244   <indexterm>
10245     <primary>array_dims</primary>
10246   </indexterm>
10247   <indexterm>
10248     <primary>array_fill</primary>
10249   </indexterm>
10250   <indexterm>
10251     <primary>array_length</primary>
10252   </indexterm>
10253   <indexterm>
10254     <primary>array_lower</primary>
10255   </indexterm>
10256   <indexterm>
10257     <primary>array_prepend</primary>
10258   </indexterm>
10259   <indexterm>
10260     <primary>array_to_string</primary>
10261   </indexterm>
10262  <indexterm>
10263     <primary>array_upper</primary>
10264   </indexterm>
10265   <indexterm>
10266     <primary>string_to_array</primary>
10267   </indexterm>
10268   <indexterm>
10269     <primary>unnest</primary>
10270   </indexterm>
10271
10272     <table id="array-functions-table">
10273      <title>Array Functions</title>
10274      <tgroup cols="5">
10275       <thead>
10276        <row>
10277         <entry>Function</entry>
10278         <entry>Return Type</entry>
10279         <entry>Description</entry>
10280         <entry>Example</entry>
10281         <entry>Result</entry>
10282        </row>
10283       </thead>
10284       <tbody>
10285        <row>
10286         <entry>
10287          <literal>
10288           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
10289          </literal>
10290         </entry>
10291         <entry><type>anyarray</type></entry>
10292         <entry>append an element to the end of an array</entry>
10293         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
10294         <entry><literal>{1,2,3}</literal></entry>
10295        </row>
10296        <row>
10297         <entry>
10298          <literal>
10299           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
10300          </literal>
10301         </entry>
10302         <entry><type>anyarray</type></entry>
10303         <entry>concatenate two arrays</entry>
10304         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
10305         <entry><literal>{1,2,3,4,5}</literal></entry>
10306        </row>
10307        <row>
10308         <entry>
10309          <literal>
10310           <function>array_ndims</function>(<type>anyarray</type>)
10311          </literal>
10312         </entry>
10313         <entry><type>int</type></entry>
10314         <entry>returns the number of dimensions of the array</entry>
10315         <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
10316         <entry><literal>2</literal></entry>
10317        </row>
10318        <row>
10319         <entry>
10320          <literal>
10321           <function>array_dims</function>(<type>anyarray</type>)
10322          </literal>
10323         </entry>
10324         <entry><type>text</type></entry>
10325         <entry>returns a text representation of array's dimensions</entry>
10326         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
10327         <entry><literal>[1:2][1:3]</literal></entry>
10328        </row>
10329        <row>
10330         <entry>
10331          <literal>
10332           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
10333           <optional>, <type>int[]</type></optional>)
10334          </literal>
10335         </entry>
10336         <entry><type>anyarray</type></entry>
10337         <entry>returns an array initialized with supplied value and
10338          dimensions, optionally with lower bounds other than 1</entry>
10339         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
10340         <entry><literal>[2:4]={7,7,7}</literal></entry>
10341        </row>
10342        <row>
10343         <entry>
10344          <literal>
10345           <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
10346          </literal>
10347         </entry>
10348         <entry><type>int</type></entry>
10349         <entry>returns the length of the requested array dimension</entry>
10350         <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
10351         <entry><literal>3</literal></entry>
10352        </row>
10353        <row>
10354         <entry>
10355          <literal>
10356           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
10357          </literal>
10358         </entry>
10359         <entry><type>int</type></entry>
10360         <entry>returns lower bound of the requested array dimension</entry>
10361         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
10362         <entry><literal>0</literal></entry>
10363        </row>
10364        <row>
10365         <entry>
10366          <literal>
10367           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
10368          </literal>
10369         </entry>
10370         <entry><type>anyarray</type></entry>
10371         <entry>append an element to the beginning of an array</entry>
10372         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
10373         <entry><literal>{1,2,3}</literal></entry>
10374        </row>
10375        <row>
10376         <entry>
10377          <literal>
10378           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type> <optional>, <type>text</type></optional>)
10379          </literal>
10380         </entry>
10381         <entry><type>text</type></entry>
10382         <entry>concatenates array elements using supplied delimiter and
10383          optional null string</entry>
10384         <entry><literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal></entry>
10385         <entry><literal>1,2,3,*,5</literal></entry>
10386        </row>
10387        <row>
10388         <entry>
10389          <literal>
10390           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
10391          </literal>
10392         </entry>
10393         <entry><type>int</type></entry>
10394         <entry>returns upper bound of the requested array dimension</entry>
10395         <entry><literal>array_upper(ARRAY[1,8,3,7], 1)</literal></entry>
10396         <entry><literal>4</literal></entry>
10397        </row>
10398        <row>
10399         <entry>
10400          <literal>
10401           <function>string_to_array</function>(<type>text</type>, <type>text</type> <optional>, <type>text</type></optional>)
10402          </literal>
10403         </entry>
10404         <entry><type>text[]</type></entry>
10405         <entry>splits string into array elements using supplied delimiter and
10406          optional null string</entry>
10407         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~', 'yy')</literal></entry>
10408         <entry><literal>{xx,NULL,zz}</literal></entry>
10409        </row>
10410        <row>
10411         <entry>
10412          <literal>
10413           <function>unnest</function>(<type>anyarray</type>)
10414          </literal>
10415         </entry>
10416         <entry><type>setof anyelement</type></entry>
10417         <entry>expand an array to a set of rows</entry>
10418         <entry><literal>unnest(ARRAY[1,2])</literal></entry>
10419         <entry><literallayout class="monospaced">1
10420 2</literallayout>(2 rows)</entry>
10421        </row>
10422       </tbody>
10423      </tgroup>
10424     </table>
10425
10426    <para>
10427     In <function>string_to_array</function>, if the delimiter parameter is
10428     NULL, each character in the input string will become a separate element in
10429     the resulting array.  If the delimiter is an empty string, then the entire
10430     input string is returned as a one-element array.  Otherwise the input
10431     string is split at each occurrence of the delimiter string.
10432    </para>
10433
10434    <para>
10435     In <function>string_to_array</function>, if the null-string parameter
10436     is omitted or NULL, none of the substrings of the input will be replaced
10437     by NULL.
10438     In <function>array_to_string</function>, if the null-string parameter
10439     is omitted or NULL, any null elements in the array are simply skipped
10440     and not represented in the output string.
10441    </para>
10442
10443    <note>
10444     <para>
10445      There are two differences in the behavior of <function>string_to_array</>
10446      from pre-9.1 versions of <productname>PostgreSQL</>.
10447      First, it will return an empty (zero-element) array rather than NULL when
10448      the input string is of zero length.  Second, if the delimiter string is
10449      NULL, the function splits the input into individual characters, rather
10450      than returning NULL as before.
10451     </para>
10452    </note>
10453
10454    <para>
10455     See also <xref linkend="functions-aggregate"> about the aggregate
10456     function <function>array_agg</function> for use with arrays.
10457    </para>
10458   </sect1>
10459
10460  <sect1 id="functions-aggregate">
10461   <title>Aggregate Functions</title>
10462
10463   <indexterm zone="functions-aggregate">
10464    <primary>aggregate function</primary>
10465    <secondary>built-in</secondary>
10466   </indexterm>
10467
10468   <para>
10469    <firstterm>Aggregate functions</firstterm> compute a single result
10470    from a set of input values.  The built-in aggregate functions
10471    are listed in
10472    <xref linkend="functions-aggregate-table"> and
10473    <xref linkend="functions-aggregate-statistics-table">.
10474    The special syntax considerations for aggregate
10475    functions are explained in <xref linkend="syntax-aggregates">.
10476    Consult <xref linkend="tutorial-agg"> for additional introductory
10477    information.
10478   </para>
10479
10480   <table id="functions-aggregate-table">
10481    <title>General-Purpose Aggregate Functions</title>
10482
10483    <tgroup cols="4">
10484     <thead>
10485      <row>
10486       <entry>Function</entry>
10487       <entry>Argument Type(s)</entry>
10488       <entry>Return Type</entry>
10489       <entry>Description</entry>
10490      </row>
10491     </thead>
10492
10493     <tbody>
10494      <row>
10495       <entry>
10496        <indexterm>
10497         <primary>array_agg</primary>
10498        </indexterm>
10499        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
10500       </entry>
10501       <entry>
10502        any
10503       </entry>
10504       <entry>
10505        array of the argument type
10506       </entry>
10507       <entry>input values, including nulls, concatenated into an array</entry>
10508      </row>
10509
10510      <row>
10511       <entry>
10512        <indexterm>
10513         <primary>average</primary>
10514        </indexterm>
10515        <indexterm>
10516         <primary>avg</primary>
10517        </indexterm>
10518        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
10519       </entry>
10520       <entry>
10521        <type>smallint</type>, <type>int</type>,
10522        <type>bigint</type>, <type>real</type>, <type>double
10523        precision</type>, <type>numeric</type>, or <type>interval</type>
10524       </entry>
10525       <entry>
10526        <type>numeric</type> for any integer-type argument,
10527        <type>double precision</type> for a floating-point argument,
10528        otherwise the same as the argument data type
10529       </entry>
10530       <entry>the average (arithmetic mean) of all input values</entry>
10531      </row>
10532
10533      <row>
10534       <entry>
10535        <indexterm>
10536         <primary>bit_and</primary>
10537        </indexterm>
10538        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
10539       </entry>
10540       <entry>
10541        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
10542        <type>bit</type>
10543       </entry>
10544       <entry>
10545         same as argument data type
10546       </entry>
10547       <entry>the bitwise AND of all non-null input values, or null if none</entry>
10548      </row>
10549
10550      <row>
10551       <entry>
10552        <indexterm>
10553         <primary>bit_or</primary>
10554        </indexterm>
10555        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
10556       </entry>
10557       <entry>
10558        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
10559        <type>bit</type>
10560       </entry>
10561       <entry>
10562         same as argument data type
10563       </entry>
10564       <entry>the bitwise OR of all non-null input values, or null if none</entry>
10565      </row>
10566
10567      <row>
10568       <entry>
10569        <indexterm>
10570         <primary>bool_and</primary>
10571        </indexterm>
10572        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
10573       </entry>
10574       <entry>
10575        <type>bool</type>
10576       </entry>
10577       <entry>
10578        <type>bool</type>
10579       </entry>
10580       <entry>true if all input values are true, otherwise false</entry>
10581      </row>
10582
10583      <row>
10584       <entry>
10585        <indexterm>
10586         <primary>bool_or</primary>
10587        </indexterm>
10588        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
10589       </entry>
10590       <entry>
10591        <type>bool</type>
10592       </entry>
10593       <entry>
10594        <type>bool</type>
10595       </entry>
10596       <entry>true if at least one input value is true, otherwise false</entry>
10597      </row>
10598
10599      <row>
10600       <entry>
10601        <indexterm>
10602         <primary>count</primary>
10603        </indexterm>
10604        <function>count(*)</function>
10605       </entry>
10606       <entry></entry>
10607       <entry><type>bigint</type></entry>
10608       <entry>number of input rows</entry>
10609      </row>
10610
10611      <row>
10612       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
10613       <entry>any</entry>
10614       <entry><type>bigint</type></entry>
10615       <entry>
10616        number of input rows for which the value of <replaceable
10617        class="parameter">expression</replaceable> is not null
10618       </entry>
10619      </row>
10620
10621      <row>
10622       <entry>
10623        <indexterm>
10624         <primary>every</primary>
10625        </indexterm>
10626        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
10627       </entry>
10628       <entry>
10629        <type>bool</type>
10630       </entry>
10631       <entry>
10632        <type>bool</type>
10633       </entry>
10634       <entry>equivalent to <function>bool_and</function></entry>
10635      </row>
10636
10637      <row>
10638       <entry>
10639        <indexterm>
10640         <primary>max</primary>
10641        </indexterm>
10642        <function>max(<replaceable class="parameter">expression</replaceable>)</function>
10643       </entry>
10644       <entry>any array, numeric, string, or date/time type</entry>
10645       <entry>same as argument type</entry>
10646       <entry>
10647        maximum value of <replaceable
10648        class="parameter">expression</replaceable> across all input
10649        values
10650       </entry>
10651      </row>
10652
10653      <row>
10654       <entry>
10655        <indexterm>
10656         <primary>min</primary>
10657        </indexterm>
10658        <function>min(<replaceable class="parameter">expression</replaceable>)</function>
10659       </entry>
10660       <entry>any array, numeric, string, or date/time type</entry>
10661       <entry>same as argument type</entry>
10662       <entry>
10663        minimum value of <replaceable
10664        class="parameter">expression</replaceable> across all input
10665        values
10666       </entry>
10667      </row>
10668
10669      <row>
10670       <entry>
10671        <indexterm>
10672         <primary>string_agg</primary>
10673        </indexterm>
10674        <function>
10675          string_agg(<replaceable class="parameter">expression</replaceable>,
10676                     <replaceable class="parameter">delimiter</replaceable>)
10677        </function>
10678       </entry>
10679       <entry>
10680        <type>text</type>, <type>text</type>
10681       </entry>
10682       <entry>
10683        <type>text</type>
10684       </entry>
10685       <entry>input values concatenated into a string, separated by delimiter</entry>
10686      </row>
10687
10688      <row>
10689       <entry>
10690        <indexterm>
10691         <primary>sum</primary>
10692        </indexterm>
10693        <function>sum(<replaceable class="parameter">expression</replaceable>)</function>
10694       </entry>
10695       <entry>
10696        <type>smallint</type>, <type>int</type>,
10697        <type>bigint</type>, <type>real</type>, <type>double
10698        precision</type>, <type>numeric</type>, or
10699        <type>interval</type>
10700       </entry>
10701       <entry>
10702        <type>bigint</type> for <type>smallint</type> or
10703        <type>int</type> arguments, <type>numeric</type> for
10704        <type>bigint</type> arguments, <type>double precision</type>
10705        for floating-point arguments, otherwise the same as the
10706        argument data type
10707       </entry>
10708       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
10709      </row>
10710
10711      <row>
10712       <entry>
10713        <indexterm>
10714         <primary>xmlagg</primary>
10715        </indexterm>
10716        <function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
10717       </entry>
10718       <entry>
10719        <type>xml</type>
10720       </entry>
10721       <entry>
10722        <type>xml</type>
10723       </entry>
10724       <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
10725      </row>
10726     </tbody>
10727    </tgroup>
10728   </table>
10729
10730   <para>
10731    It should be noted that except for <function>count</function>,
10732    these functions return a null value when no rows are selected.  In
10733    particular, <function>sum</function> of no rows returns null, not
10734    zero as one might expect, and <function>array_agg</function>
10735    returns null rather than an empty array when there are no input
10736    rows.  The <function>coalesce</function> function can be used to
10737    substitute zero or an empty array for null when necessary.
10738   </para>
10739
10740   <note>
10741     <indexterm>
10742       <primary>ANY</primary>
10743     </indexterm>
10744     <indexterm>
10745       <primary>SOME</primary>
10746     </indexterm>
10747     <para>
10748       Boolean aggregates <function>bool_and</function> and
10749       <function>bool_or</function> correspond to standard SQL aggregates
10750       <function>every</function> and <function>any</function> or
10751       <function>some</function>.
10752       As for <function>any</function> and <function>some</function>,
10753       it seems that there is an ambiguity built into the standard syntax:
10754 <programlisting>
10755 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
10756 </programlisting>
10757       Here <function>ANY</function> can be considered either as introducing
10758       a subquery, or as being an aggregate function, if the subquery
10759       returns one row with a Boolean value.
10760       Thus the standard name cannot be given to these aggregates.
10761     </para>
10762   </note>
10763
10764   <note>
10765    <para>
10766     Users accustomed to working with other SQL database management
10767     systems might be disappointed by the performance of the
10768     <function>count</function> aggregate when it is applied to the
10769     entire table. A query like:
10770 <programlisting>
10771 SELECT count(*) FROM sometable;
10772 </programlisting>
10773     will be executed by <productname>PostgreSQL</productname> using a
10774     sequential scan of the entire table.
10775    </para>
10776   </note>
10777
10778   <para>
10779    The aggregate functions <function>array_agg</function>,
10780    <function>string_agg</function>,
10781    and <function>xmlagg</function>, as well as similar user-defined
10782    aggregate functions, produce meaningfully different result values
10783    depending on the order of the input values.  This ordering is
10784    unspecified by default, but can be controlled by writing an
10785    <literal>ORDER BY</> clause within the aggregate call, as shown in
10786    <xref linkend="syntax-aggregates">.
10787    Alternatively, supplying the input values from a sorted subquery
10788    will usually work.  For example:
10789
10790 <screen><![CDATA[
10791 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
10792 ]]></screen>
10793
10794    But this syntax is not allowed in the SQL standard, and is
10795    not portable to other database systems.
10796   </para>
10797
10798   <para>
10799    <xref linkend="functions-aggregate-statistics-table"> shows
10800    aggregate functions typically used in statistical analysis.
10801    (These are separated out merely to avoid cluttering the listing
10802    of more-commonly-used aggregates.)  Where the description mentions
10803    <replaceable class="parameter">N</replaceable>, it means the
10804    number of input rows for which all the input expressions are non-null.
10805    In all cases, null is returned if the computation is meaningless,
10806    for example when <replaceable class="parameter">N</replaceable> is zero.
10807   </para>
10808
10809   <indexterm>
10810    <primary>statistics</primary>
10811   </indexterm>
10812   <indexterm>
10813    <primary>linear regression</primary>
10814   </indexterm>
10815
10816   <table id="functions-aggregate-statistics-table">
10817    <title>Aggregate Functions for Statistics</title>
10818
10819    <tgroup cols="4">
10820     <thead>
10821      <row>
10822       <entry>Function</entry>
10823       <entry>Argument Type</entry>
10824       <entry>Return Type</entry>
10825       <entry>Description</entry>
10826      </row>
10827     </thead>
10828
10829     <tbody>
10830
10831      <row>
10832       <entry>
10833        <indexterm>
10834         <primary>correlation</primary>
10835        </indexterm>
10836        <indexterm>
10837         <primary>corr</primary>
10838        </indexterm>
10839        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10840       </entry>
10841       <entry>
10842        <type>double precision</type>
10843       </entry>
10844       <entry>
10845        <type>double precision</type>
10846       </entry>
10847       <entry>correlation coefficient</entry>
10848      </row>
10849
10850      <row>
10851       <entry>
10852        <indexterm>
10853         <primary>covariance</primary>
10854         <secondary>population</secondary>
10855        </indexterm>
10856        <indexterm>
10857         <primary>covar_pop</primary>
10858        </indexterm>
10859        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10860       </entry>
10861       <entry>
10862        <type>double precision</type>
10863       </entry>
10864       <entry>
10865        <type>double precision</type>
10866       </entry>
10867       <entry>population covariance</entry>
10868      </row>
10869
10870      <row>
10871       <entry>
10872        <indexterm>
10873         <primary>covariance</primary>
10874         <secondary>sample</secondary>
10875        </indexterm>
10876        <indexterm>
10877         <primary>covar_samp</primary>
10878        </indexterm>
10879        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10880       </entry>
10881       <entry>
10882        <type>double precision</type>
10883       </entry>
10884       <entry>
10885        <type>double precision</type>
10886       </entry>
10887       <entry>sample covariance</entry>
10888      </row>
10889
10890      <row>
10891       <entry>
10892        <indexterm>
10893         <primary>regr_avgx</primary>
10894        </indexterm>
10895        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10896       </entry>
10897       <entry>
10898        <type>double precision</type>
10899       </entry>
10900       <entry>
10901        <type>double precision</type>
10902       </entry>
10903       <entry>average of the independent variable
10904       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
10905      </row>
10906
10907      <row>
10908       <entry>
10909        <indexterm>
10910         <primary>regr_avgy</primary>
10911        </indexterm>
10912        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10913       </entry>
10914       <entry>
10915        <type>double precision</type>
10916       </entry>
10917       <entry>
10918        <type>double precision</type>
10919       </entry>
10920       <entry>average of the dependent variable
10921       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
10922      </row>
10923
10924      <row>
10925       <entry>
10926        <indexterm>
10927         <primary>regr_count</primary>
10928        </indexterm>
10929        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10930       </entry>
10931       <entry>
10932        <type>double precision</type>
10933       </entry>
10934       <entry>
10935        <type>bigint</type>
10936       </entry>
10937       <entry>number of input rows in which both expressions are nonnull</entry>
10938      </row>
10939
10940      <row>
10941       <entry>
10942        <indexterm>
10943         <primary>regression intercept</primary>
10944        </indexterm>
10945        <indexterm>
10946         <primary>regr_intercept</primary>
10947        </indexterm>
10948        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10949       </entry>
10950       <entry>
10951        <type>double precision</type>
10952       </entry>
10953       <entry>
10954        <type>double precision</type>
10955       </entry>
10956       <entry>y-intercept of the least-squares-fit linear equation
10957       determined by the (<replaceable
10958       class="parameter">X</replaceable>, <replaceable
10959       class="parameter">Y</replaceable>) pairs</entry>
10960      </row>
10961
10962      <row>
10963       <entry>
10964        <indexterm>
10965         <primary>regr_r2</primary>
10966        </indexterm>
10967        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10968       </entry>
10969       <entry>
10970        <type>double precision</type>
10971       </entry>
10972       <entry>
10973        <type>double precision</type>
10974       </entry>
10975       <entry>square of the correlation coefficient</entry>
10976      </row>
10977
10978      <row>
10979       <entry>
10980        <indexterm>
10981         <primary>regression slope</primary>
10982        </indexterm>
10983        <indexterm>
10984         <primary>regr_slope</primary>
10985        </indexterm>
10986        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10987       </entry>
10988       <entry>
10989        <type>double precision</type>
10990       </entry>
10991       <entry>
10992        <type>double precision</type>
10993       </entry>
10994       <entry>slope of the least-squares-fit linear equation determined
10995       by the (<replaceable class="parameter">X</replaceable>,
10996       <replaceable class="parameter">Y</replaceable>) pairs</entry>
10997      </row>
10998
10999      <row>
11000       <entry>
11001        <indexterm>
11002         <primary>regr_sxx</primary>
11003        </indexterm>
11004        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11005       </entry>
11006       <entry>
11007        <type>double precision</type>
11008       </entry>
11009       <entry>
11010        <type>double precision</type>
11011       </entry>
11012       <entry><literal>sum(<replaceable
11013       class="parameter">X</replaceable>^2) - sum(<replaceable
11014       class="parameter">X</replaceable>)^2/<replaceable
11015       class="parameter">N</replaceable></literal> (<quote>sum of
11016       squares</quote> of the independent variable)</entry>
11017      </row>
11018
11019      <row>
11020       <entry>
11021        <indexterm>
11022         <primary>regr_sxy</primary>
11023        </indexterm>
11024        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11025       </entry>
11026       <entry>
11027        <type>double precision</type>
11028       </entry>
11029       <entry>
11030        <type>double precision</type>
11031       </entry>
11032       <entry><literal>sum(<replaceable
11033       class="parameter">X</replaceable>*<replaceable
11034       class="parameter">Y</replaceable>) - sum(<replaceable
11035       class="parameter">X</replaceable>) * sum(<replaceable
11036       class="parameter">Y</replaceable>)/<replaceable
11037       class="parameter">N</replaceable></literal> (<quote>sum of
11038       products</quote> of independent times dependent
11039       variable)</entry>
11040      </row>
11041
11042      <row>
11043       <entry>
11044        <indexterm>
11045         <primary>regr_syy</primary>
11046        </indexterm>
11047        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11048       </entry>
11049       <entry>
11050        <type>double precision</type>
11051       </entry>
11052       <entry>
11053        <type>double precision</type>
11054       </entry>
11055       <entry><literal>sum(<replaceable
11056       class="parameter">Y</replaceable>^2) - sum(<replaceable
11057       class="parameter">Y</replaceable>)^2/<replaceable
11058       class="parameter">N</replaceable></literal> (<quote>sum of
11059       squares</quote> of the dependent variable)</entry>
11060      </row>
11061
11062      <row>
11063       <entry>
11064        <indexterm>
11065         <primary>standard deviation</primary>
11066        </indexterm>
11067        <indexterm>
11068         <primary>stddev</primary>
11069        </indexterm>
11070        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
11071       </entry>
11072       <entry>
11073        <type>smallint</type>, <type>int</type>,
11074        <type>bigint</type>, <type>real</type>, <type>double
11075        precision</type>, or <type>numeric</type>
11076       </entry>
11077       <entry>
11078        <type>double precision</type> for floating-point arguments,
11079        otherwise <type>numeric</type>
11080       </entry>
11081       <entry>historical alias for <function>stddev_samp</function></entry>
11082      </row>
11083
11084      <row>
11085       <entry>
11086        <indexterm>
11087         <primary>standard deviation</primary>
11088         <secondary>population</secondary>
11089        </indexterm>
11090        <indexterm>
11091         <primary>stddev_pop</primary>
11092        </indexterm>
11093        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
11094       </entry>
11095       <entry>
11096        <type>smallint</type>, <type>int</type>,
11097        <type>bigint</type>, <type>real</type>, <type>double
11098        precision</type>, or <type>numeric</type>
11099       </entry>
11100       <entry>
11101        <type>double precision</type> for floating-point arguments,
11102        otherwise <type>numeric</type>
11103       </entry>
11104       <entry>population standard deviation of the input values</entry>
11105      </row>
11106
11107      <row>
11108       <entry>
11109        <indexterm>
11110         <primary>standard deviation</primary>
11111         <secondary>sample</secondary>
11112        </indexterm>
11113        <indexterm>
11114         <primary>stddev_samp</primary>
11115        </indexterm>
11116        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
11117       </entry>
11118       <entry>
11119        <type>smallint</type>, <type>int</type>,
11120        <type>bigint</type>, <type>real</type>, <type>double
11121        precision</type>, or <type>numeric</type>
11122       </entry>
11123       <entry>
11124        <type>double precision</type> for floating-point arguments,
11125        otherwise <type>numeric</type>
11126       </entry>
11127       <entry>sample standard deviation of the input values</entry>
11128      </row>
11129
11130      <row>
11131       <entry>
11132        <indexterm>
11133         <primary>variance</primary>
11134        </indexterm>
11135        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
11136       </entry>
11137       <entry>
11138        <type>smallint</type>, <type>int</type>,
11139        <type>bigint</type>, <type>real</type>, <type>double
11140        precision</type>, or <type>numeric</type>
11141       </entry>
11142       <entry>
11143        <type>double precision</type> for floating-point arguments,
11144        otherwise <type>numeric</type>
11145       </entry>
11146       <entry>historical alias for <function>var_samp</function></entry>
11147      </row>
11148
11149      <row>
11150       <entry>
11151        <indexterm>
11152         <primary>variance</primary>
11153         <secondary>population</secondary>
11154        </indexterm>
11155        <indexterm>
11156         <primary>var_pop</primary>
11157        </indexterm>
11158        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
11159       </entry>
11160       <entry>
11161        <type>smallint</type>, <type>int</type>,
11162        <type>bigint</type>, <type>real</type>, <type>double
11163        precision</type>, or <type>numeric</type>
11164       </entry>
11165       <entry>
11166        <type>double precision</type> for floating-point arguments,
11167        otherwise <type>numeric</type>
11168       </entry>
11169       <entry>population variance of the input values (square of the population standard deviation)</entry>
11170      </row>
11171
11172      <row>
11173       <entry>
11174        <indexterm>
11175         <primary>variance</primary>
11176         <secondary>sample</secondary>
11177        </indexterm>
11178        <indexterm>
11179         <primary>var_samp</primary>
11180        </indexterm>
11181        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
11182       </entry>
11183       <entry>
11184        <type>smallint</type>, <type>int</type>,
11185        <type>bigint</type>, <type>real</type>, <type>double
11186        precision</type>, or <type>numeric</type>
11187       </entry>
11188       <entry>
11189        <type>double precision</type> for floating-point arguments,
11190        otherwise <type>numeric</type>
11191       </entry>
11192       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
11193      </row>
11194     </tbody>
11195    </tgroup>
11196   </table>
11197
11198  </sect1>
11199
11200  <sect1 id="functions-window">
11201   <title>Window Functions</title>
11202
11203   <indexterm zone="functions-window">
11204    <primary>window function</primary>
11205    <secondary>built-in</secondary>
11206   </indexterm>
11207
11208   <para>
11209    <firstterm>Window functions</firstterm> provide the ability to perform
11210    calculations across sets of rows that are related to the current query
11211    row.  See <xref linkend="tutorial-window"> for an introduction to this
11212    feature.
11213   </para>
11214
11215   <para>
11216    The built-in window functions are listed in
11217    <xref linkend="functions-window-table">.  Note that these functions
11218    <emphasis>must</> be invoked using window function syntax; that is an
11219    <literal>OVER</> clause is required.
11220   </para>
11221
11222   <para>
11223    In addition to these functions, any built-in or user-defined aggregate
11224    function can be used as a window function (see
11225    <xref linkend="functions-aggregate"> for a list of the built-in aggregates).
11226    Aggregate functions act as window functions only when an <literal>OVER</>
11227    clause follows the call; otherwise they act as regular aggregates.
11228   </para>
11229
11230   <table id="functions-window-table">
11231    <title>General-Purpose Window Functions</title>
11232
11233    <tgroup cols="3">
11234     <thead>
11235      <row>
11236       <entry>Function</entry>
11237       <entry>Return Type</entry>
11238       <entry>Description</entry>
11239      </row>
11240     </thead>
11241
11242     <tbody>
11243      <row>
11244       <entry>
11245        <indexterm>
11246         <primary>row_number</primary>
11247        </indexterm>
11248        <function>row_number()</function>
11249       </entry>
11250       <entry>
11251        <type>bigint</type>
11252       </entry>
11253       <entry>number of the current row within its partition, counting from 1</entry>
11254      </row>
11255
11256      <row>
11257       <entry>
11258        <indexterm>
11259         <primary>rank</primary>
11260        </indexterm>
11261        <function>rank()</function>
11262       </entry>
11263       <entry>
11264        <type>bigint</type>
11265       </entry>
11266       <entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
11267      </row>
11268
11269      <row>
11270       <entry>
11271        <indexterm>
11272         <primary>dense_rank</primary>
11273        </indexterm>
11274        <function>dense_rank()</function>
11275       </entry>
11276       <entry>
11277        <type>bigint</type>
11278       </entry>
11279       <entry>rank of the current row without gaps; this function counts peer groups</entry>
11280      </row>
11281
11282      <row>
11283       <entry>
11284        <indexterm>
11285         <primary>percent_rank</primary>
11286        </indexterm>
11287        <function>percent_rank()</function>
11288       </entry>
11289       <entry>
11290        <type>double precision</type>
11291       </entry>
11292       <entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
11293      </row>
11294
11295      <row>
11296       <entry>
11297        <indexterm>
11298         <primary>cume_dist</primary>
11299        </indexterm>
11300        <function>cume_dist()</function>
11301       </entry>
11302       <entry>
11303        <type>double precision</type>
11304       </entry>
11305       <entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
11306      </row>
11307
11308      <row>
11309       <entry>
11310        <indexterm>
11311         <primary>ntile</primary>
11312        </indexterm>
11313        <function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</>)</function>
11314       </entry>
11315       <entry>
11316        <type>integer</type>
11317       </entry>
11318       <entry>integer ranging from 1 to the argument value, dividing the
11319        partition as equally as possible</entry>
11320      </row>
11321
11322      <row>
11323       <entry>
11324        <indexterm>
11325         <primary>lag</primary>
11326        </indexterm>
11327        <function>
11328          lag(<replaceable class="parameter">value</replaceable> <type>any</>
11329              [, <replaceable class="parameter">offset</replaceable> <type>integer</>
11330              [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
11331        </function>
11332       </entry>
11333       <entry>
11334        <type>same type as <replaceable class="parameter">value</replaceable></type>
11335       </entry>
11336       <entry>
11337        returns <replaceable class="parameter">value</replaceable> evaluated at
11338        the row that is <replaceable class="parameter">offset</replaceable>
11339        rows before the current row within the partition; if there is no such
11340        row, instead return <replaceable class="parameter">default</replaceable>.
11341        Both <replaceable class="parameter">offset</replaceable> and
11342        <replaceable class="parameter">default</replaceable> are evaluated
11343        with respect to the current row.  If omitted,
11344        <replaceable class="parameter">offset</replaceable> defaults to 1 and
11345        <replaceable class="parameter">default</replaceable> to null
11346       </entry>
11347      </row>
11348
11349      <row>
11350       <entry>
11351        <indexterm>
11352         <primary>lead</primary>
11353        </indexterm>
11354        <function>
11355          lead(<replaceable class="parameter">value</replaceable> <type>any</>
11356               [, <replaceable class="parameter">offset</replaceable> <type>integer</>
11357               [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
11358        </function>
11359       </entry>
11360       <entry>
11361        <type>same type as <replaceable class="parameter">value</replaceable></type>
11362       </entry>
11363       <entry>
11364        returns <replaceable class="parameter">value</replaceable> evaluated at
11365        the row that is <replaceable class="parameter">offset</replaceable>
11366        rows after the current row within the partition; if there is no such
11367        row, instead return <replaceable class="parameter">default</replaceable>.
11368        Both <replaceable class="parameter">offset</replaceable> and
11369        <replaceable class="parameter">default</replaceable> are evaluated
11370        with respect to the current row.  If omitted,
11371        <replaceable class="parameter">offset</replaceable> defaults to 1 and
11372        <replaceable class="parameter">default</replaceable> to null
11373       </entry>
11374      </row>
11375
11376      <row>
11377       <entry>
11378        <indexterm>
11379         <primary>first_value</primary>
11380        </indexterm>
11381        <function>first_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
11382       </entry>
11383       <entry>
11384        <type>same type as <replaceable class="parameter">value</replaceable></type>
11385       </entry>
11386       <entry>
11387        returns <replaceable class="parameter">value</replaceable> evaluated
11388        at the row that is the first row of the window frame
11389       </entry>
11390      </row>
11391
11392      <row>
11393       <entry>
11394        <indexterm>
11395         <primary>last_value</primary>
11396        </indexterm>
11397        <function>last_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
11398       </entry>
11399       <entry>
11400        <type>same type as <replaceable class="parameter">value</replaceable></type>
11401       </entry>
11402       <entry>
11403        returns <replaceable class="parameter">value</replaceable> evaluated
11404        at the row that is the last row of the window frame
11405       </entry>
11406      </row>
11407
11408      <row>
11409       <entry>
11410        <indexterm>
11411         <primary>nth_value</primary>
11412        </indexterm>
11413        <function>
11414          nth_value(<replaceable class="parameter">value</replaceable> <type>any</>, <replaceable class="parameter">nth</replaceable> <type>integer</>)
11415        </function>
11416       </entry>
11417       <entry>
11418        <type>same type as <replaceable class="parameter">value</replaceable></type>
11419       </entry>
11420       <entry>
11421        returns <replaceable class="parameter">value</replaceable> evaluated
11422        at the row that is the <replaceable class="parameter">nth</replaceable>
11423        row of the window frame (counting from 1); null if no such row
11424       </entry>
11425      </row>
11426     </tbody>
11427    </tgroup>
11428   </table>
11429
11430   <para>
11431    All of the functions listed in
11432    <xref linkend="functions-window-table"> depend on the sort ordering
11433    specified by the <literal>ORDER BY</> clause of the associated window
11434    definition.  Rows that are not distinct in the <literal>ORDER BY</>
11435    ordering are said to be <firstterm>peers</>; the four ranking functions
11436    are defined so that they give the same answer for any two peer rows.
11437   </para>
11438
11439   <para>
11440    Note that <function>first_value</>, <function>last_value</>, and
11441    <function>nth_value</> consider only the rows within the <quote>window
11442    frame</>, which by default contains the rows from the start of the
11443    partition through the last peer of the current row.  This is
11444    likely to give unhelpful results for <function>last_value</> and
11445    sometimes also <function>nth_value</>.  You can redefine the frame by
11446    adding a suitable frame specification (<literal>RANGE</> or
11447    <literal>ROWS</>) to the <literal>OVER</> clause.
11448    See <xref linkend="syntax-window-functions"> for more information
11449    about frame specifications.
11450   </para>
11451
11452   <para>
11453    When an aggregate function is used as a window function, it aggregates
11454    over the rows within the current row's window frame.
11455    An aggregate used with <literal>ORDER BY</> and the default window frame
11456    definition produces a <quote>running sum</> type of behavior, which may or
11457    may not be what's wanted.  To obtain
11458    aggregation over the whole partition, omit <literal>ORDER BY</> or use
11459    <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
11460    Other frame specifications can be used to obtain other effects.
11461   </para>
11462
11463   <note>
11464    <para>
11465     The SQL standard defines a <literal>RESPECT NULLS</> or
11466     <literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
11467     <function>first_value</>, <function>last_value</>, and
11468     <function>nth_value</>.  This is not implemented in
11469     <productname>PostgreSQL</productname>: the behavior is always the
11470     same as the standard's default, namely <literal>RESPECT NULLS</>.
11471     Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
11472     option for <function>nth_value</> is not implemented: only the
11473     default <literal>FROM FIRST</> behavior is supported.  (You can achieve
11474     the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
11475     ordering.)
11476    </para>
11477   </note>
11478
11479  </sect1>
11480
11481  <sect1 id="functions-subquery">
11482   <title>Subquery Expressions</title>
11483
11484   <indexterm>
11485    <primary>EXISTS</primary>
11486   </indexterm>
11487
11488   <indexterm>
11489    <primary>IN</primary>
11490   </indexterm>
11491
11492   <indexterm>
11493    <primary>NOT IN</primary>
11494   </indexterm>
11495
11496   <indexterm>
11497    <primary>ANY</primary>
11498   </indexterm>
11499
11500   <indexterm>
11501    <primary>ALL</primary>
11502   </indexterm>
11503
11504   <indexterm>
11505    <primary>SOME</primary>
11506   </indexterm>
11507
11508   <indexterm>
11509    <primary>subquery</primary>
11510   </indexterm>
11511
11512   <para>
11513    This section describes the <acronym>SQL</acronym>-compliant subquery
11514    expressions available in <productname>PostgreSQL</productname>.
11515    All of the expression forms documented in this section return
11516    Boolean (true/false) results.
11517   </para>
11518
11519   <sect2 id="functions-subquery-exists">
11520    <title><literal>EXISTS</literal></title>
11521
11522 <synopsis>
11523 EXISTS (<replaceable>subquery</replaceable>)
11524 </synopsis>
11525
11526   <para>
11527    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
11528    or <firstterm>subquery</firstterm>.  The
11529    subquery is evaluated to determine whether it returns any rows.
11530    If it returns at least one row, the result of <token>EXISTS</token> is
11531    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
11532    is <quote>false</>.
11533   </para>
11534
11535   <para>
11536    The subquery can refer to variables from the surrounding query,
11537    which will act as constants during any one evaluation of the subquery.
11538   </para>
11539
11540   <para>
11541    The subquery will generally only be executed long enough to determine
11542    whether at least one row is returned, not all the way to completion.
11543    It is unwise to write a subquery that has side effects (such as
11544    calling sequence functions); whether the side effects occur
11545    might be unpredictable.
11546   </para>
11547
11548   <para>
11549    Since the result depends only on whether any rows are returned,
11550    and not on the contents of those rows, the output list of the
11551    subquery is normally unimportant.  A common coding convention is
11552    to write all <literal>EXISTS</> tests in the form
11553    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
11554    this rule however, such as subqueries that use <token>INTERSECT</token>.
11555   </para>
11556
11557   <para>
11558    This simple example is like an inner join on <literal>col2</>, but
11559    it produces at most one output row for each <literal>tab1</> row,
11560    even if there are several matching <literal>tab2</> rows:
11561 <screen>
11562 SELECT col1
11563 FROM tab1
11564 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
11565 </screen>
11566   </para>
11567   </sect2>
11568
11569   <sect2 id="functions-subquery-in">
11570    <title><literal>IN</literal></title>
11571
11572 <synopsis>
11573 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
11574 </synopsis>
11575
11576   <para>
11577    The right-hand side is a parenthesized
11578    subquery, which must return exactly one column.  The left-hand expression
11579    is evaluated and compared to each row of the subquery result.
11580    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
11581    The result is <quote>false</> if no equal row is found (including the
11582    case where the subquery returns no rows).
11583   </para>
11584
11585   <para>
11586    Note that if the left-hand expression yields null, or if there are
11587    no equal right-hand values and at least one right-hand row yields
11588    null, the result of the <token>IN</token> construct will be null, not false.
11589    This is in accordance with SQL's normal rules for Boolean combinations
11590    of null values.
11591   </para>
11592
11593   <para>
11594    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
11595    be evaluated completely.
11596   </para>
11597
11598 <synopsis>
11599 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
11600 </synopsis>
11601
11602   <para>
11603    The left-hand side of this form of <token>IN</token> is a row constructor,
11604    as described in <xref linkend="sql-syntax-row-constructors">.
11605    The right-hand side is a parenthesized
11606    subquery, which must return exactly as many columns as there are
11607    expressions in the left-hand row.  The left-hand expressions are
11608    evaluated and compared row-wise to each row of the subquery result.
11609    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
11610    The result is <quote>false</> if no equal row is found (including the
11611    case where the subquery returns no rows).
11612   </para>
11613
11614   <para>
11615    As usual, null values in the rows are combined per
11616    the normal rules of SQL Boolean expressions.  Two rows are considered
11617    equal if all their corresponding members are non-null and equal; the rows
11618    are unequal if any corresponding members are non-null and unequal;
11619    otherwise the result of that row comparison is unknown (null).
11620    If all the per-row results are either unequal or null, with at least one
11621    null, then the result of <token>IN</token> is null.
11622   </para>
11623   </sect2>
11624
11625   <sect2 id="functions-subquery-notin">
11626    <title><literal>NOT IN</literal></title>
11627
11628 <synopsis>
11629 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
11630 </synopsis>
11631
11632   <para>
11633    The right-hand side is a parenthesized
11634    subquery, which must return exactly one column.  The left-hand expression
11635    is evaluated and compared to each row of the subquery result.
11636    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
11637    are found (including the case where the subquery returns no rows).
11638    The result is <quote>false</> if any equal row is found.
11639   </para>
11640
11641   <para>
11642    Note that if the left-hand expression yields null, or if there are
11643    no equal right-hand values and at least one right-hand row yields
11644    null, the result of the <token>NOT IN</token> construct will be null, not true.
11645    This is in accordance with SQL's normal rules for Boolean combinations
11646    of null values.
11647   </para>
11648
11649   <para>
11650    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
11651    be evaluated completely.
11652   </para>
11653
11654 <synopsis>
11655 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
11656 </synopsis>
11657
11658   <para>
11659    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
11660    as described in <xref linkend="sql-syntax-row-constructors">.
11661    The right-hand side is a parenthesized
11662    subquery, which must return exactly as many columns as there are
11663    expressions in the left-hand row.  The left-hand expressions are
11664    evaluated and compared row-wise to each row of the subquery result.
11665    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
11666    are found (including the case where the subquery returns no rows).
11667    The result is <quote>false</> if any equal row is found.
11668   </para>
11669
11670   <para>
11671    As usual, null values in the rows are combined per
11672    the normal rules of SQL Boolean expressions.  Two rows are considered
11673    equal if all their corresponding members are non-null and equal; the rows
11674    are unequal if any corresponding members are non-null and unequal;
11675    otherwise the result of that row comparison is unknown (null).
11676    If all the per-row results are either unequal or null, with at least one
11677    null, then the result of <token>NOT IN</token> is null.
11678   </para>
11679   </sect2>
11680
11681   <sect2 id="functions-subquery-any-some">
11682    <title><literal>ANY</literal>/<literal>SOME</literal></title>
11683
11684 <synopsis>
11685 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
11686 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
11687 </synopsis>
11688
11689   <para>
11690    The right-hand side is a parenthesized
11691    subquery, which must return exactly one column.  The left-hand expression
11692    is evaluated and compared to each row of the subquery result using the
11693    given <replaceable>operator</replaceable>, which must yield a Boolean
11694    result.
11695    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
11696    The result is <quote>false</> if no true result is found (including the
11697    case where the subquery returns no rows).
11698   </para>
11699
11700   <para>
11701    <token>SOME</token> is a synonym for <token>ANY</token>.
11702    <token>IN</token> is equivalent to <literal>= ANY</literal>.
11703   </para>
11704
11705   <para>
11706    Note that if there are no successes and at least one right-hand row yields
11707    null for the operator's result, the result of the <token>ANY</token> construct
11708    will be null, not false.
11709    This is in accordance with SQL's normal rules for Boolean combinations
11710    of null values.
11711   </para>
11712
11713   <para>
11714    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
11715    be evaluated completely.
11716   </para>
11717
11718 <synopsis>
11719 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
11720 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
11721 </synopsis>
11722
11723   <para>
11724    The left-hand side of this form of <token>ANY</token> is a row constructor,
11725    as described in <xref linkend="sql-syntax-row-constructors">.
11726    The right-hand side is a parenthesized
11727    subquery, which must return exactly as many columns as there are
11728    expressions in the left-hand row.  The left-hand expressions are
11729    evaluated and compared row-wise to each row of the subquery result,
11730    using the given <replaceable>operator</replaceable>.
11731    The result of <token>ANY</token> is <quote>true</> if the comparison
11732    returns true for any subquery row.
11733    The result is <quote>false</> if the comparison returns false for every
11734    subquery row (including the case where the subquery returns no
11735    rows).
11736    The result is NULL if the comparison does not return true for any row,
11737    and it returns NULL for at least one row.
11738   </para>
11739
11740   <para>
11741    See <xref linkend="row-wise-comparison"> for details about the meaning
11742    of a row-wise comparison.
11743   </para>
11744   </sect2>
11745
11746   <sect2 id="functions-subquery-all">
11747    <title><literal>ALL</literal></title>
11748
11749 <synopsis>
11750 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
11751 </synopsis>
11752
11753   <para>
11754    The right-hand side is a parenthesized
11755    subquery, which must return exactly one column.  The left-hand expression
11756    is evaluated and compared to each row of the subquery result using the
11757    given <replaceable>operator</replaceable>, which must yield a Boolean
11758    result.
11759    The result of <token>ALL</token> is <quote>true</> if all rows yield true
11760    (including the case where the subquery returns no rows).
11761    The result is <quote>false</> if any false result is found.
11762    The result is NULL if the comparison does not return false for any row,
11763    and it returns NULL for at least one row.
11764   </para>
11765
11766   <para>
11767    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
11768   </para>
11769
11770   <para>
11771    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
11772    be evaluated completely.
11773   </para>
11774
11775 <synopsis>
11776 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
11777 </synopsis>
11778
11779   <para>
11780    The left-hand side of this form of <token>ALL</token> is a row constructor,
11781    as described in <xref linkend="sql-syntax-row-constructors">.
11782    The right-hand side is a parenthesized
11783    subquery, which must return exactly as many columns as there are
11784    expressions in the left-hand row.  The left-hand expressions are
11785    evaluated and compared row-wise to each row of the subquery result,
11786    using the given <replaceable>operator</replaceable>.
11787    The result of <token>ALL</token> is <quote>true</> if the comparison
11788    returns true for all subquery rows (including the
11789    case where the subquery returns no rows).
11790    The result is <quote>false</> if the comparison returns false for any
11791    subquery row.
11792    The result is NULL if the comparison does not return false for any
11793    subquery row, and it returns NULL for at least one row.
11794   </para>
11795
11796   <para>
11797    See <xref linkend="row-wise-comparison"> for details about the meaning
11798    of a row-wise comparison.
11799   </para>
11800   </sect2>
11801
11802   <sect2>
11803    <title>Row-wise Comparison</title>
11804
11805    <indexterm zone="functions-subquery">
11806     <primary>comparison</primary>
11807     <secondary>subquery result row</secondary>
11808    </indexterm>
11809
11810 <synopsis>
11811 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
11812 </synopsis>
11813
11814   <para>
11815    The left-hand side is a row constructor,
11816    as described in <xref linkend="sql-syntax-row-constructors">.
11817    The right-hand side is a parenthesized subquery, which must return exactly
11818    as many columns as there are expressions in the left-hand row. Furthermore,
11819    the subquery cannot return more than one row.  (If it returns zero rows,
11820    the result is taken to be null.)  The left-hand side is evaluated and
11821    compared row-wise to the single subquery result row.
11822   </para>
11823
11824   <para>
11825    See <xref linkend="row-wise-comparison"> for details about the meaning
11826    of a row-wise comparison.
11827   </para>
11828   </sect2>
11829  </sect1>
11830
11831
11832  <sect1 id="functions-comparisons">
11833   <title>Row and Array Comparisons</title>
11834
11835   <indexterm>
11836    <primary>IN</primary>
11837   </indexterm>
11838
11839   <indexterm>
11840    <primary>NOT IN</primary>
11841   </indexterm>
11842
11843   <indexterm>
11844    <primary>ANY</primary>
11845   </indexterm>
11846
11847   <indexterm>
11848    <primary>ALL</primary>
11849   </indexterm>
11850
11851   <indexterm>
11852    <primary>SOME</primary>
11853   </indexterm>
11854
11855   <indexterm>
11856    <primary>row-wise comparison</primary>
11857   </indexterm>
11858
11859   <indexterm>
11860    <primary>comparison</primary>
11861    <secondary>row-wise</secondary>
11862   </indexterm>
11863
11864   <indexterm>
11865    <primary>IS DISTINCT FROM</primary>
11866   </indexterm>
11867
11868   <indexterm>
11869    <primary>IS NOT DISTINCT FROM</primary>
11870   </indexterm>
11871
11872   <para>
11873    This section describes several specialized constructs for making
11874    multiple comparisons between groups of values.  These forms are
11875    syntactically related to the subquery forms of the previous section,
11876    but do not involve subqueries.
11877    The forms involving array subexpressions are
11878    <productname>PostgreSQL</productname> extensions; the rest are
11879    <acronym>SQL</acronym>-compliant.
11880    All of the expression forms documented in this section return
11881    Boolean (true/false) results.
11882   </para>
11883
11884   <sect2>
11885    <title><literal>IN</literal></title>
11886
11887 <synopsis>
11888 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
11889 </synopsis>
11890
11891   <para>
11892    The right-hand side is a parenthesized list
11893    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
11894    result is equal to any of the right-hand expressions.  This is a shorthand
11895    notation for
11896
11897 <synopsis>
11898 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
11899 OR
11900 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
11901 OR
11902 ...
11903 </synopsis>
11904   </para>
11905
11906   <para>
11907    Note that if the left-hand expression yields null, or if there are
11908    no equal right-hand values and at least one right-hand expression yields
11909    null, the result of the <token>IN</token> construct will be null, not false.
11910    This is in accordance with SQL's normal rules for Boolean combinations
11911    of null values.
11912   </para>
11913   </sect2>
11914
11915   <sect2>
11916    <title><literal>NOT IN</literal></title>
11917
11918 <synopsis>
11919 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
11920 </synopsis>
11921
11922   <para>
11923    The right-hand side is a parenthesized list
11924    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
11925    result is unequal to all of the right-hand expressions.  This is a shorthand
11926    notation for
11927
11928 <synopsis>
11929 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
11930 AND
11931 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
11932 AND
11933 ...
11934 </synopsis>
11935   </para>
11936
11937   <para>
11938    Note that if the left-hand expression yields null, or if there are
11939    no equal right-hand values and at least one right-hand expression yields
11940    null, the result of the <token>NOT IN</token> construct will be null, not true
11941    as one might naively expect.
11942    This is in accordance with SQL's normal rules for Boolean combinations
11943    of null values.
11944   </para>
11945
11946   <tip>
11947   <para>
11948    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
11949    cases.  However, null values are much more likely to trip up the novice when
11950    working with <token>NOT IN</token> than when working with <token>IN</token>.
11951    It is best to express your condition positively if possible.
11952   </para>
11953   </tip>
11954   </sect2>
11955
11956   <sect2>
11957    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
11958
11959 <synopsis>
11960 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
11961 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
11962 </synopsis>
11963
11964   <para>
11965    The right-hand side is a parenthesized expression, which must yield an
11966    array value.
11967    The left-hand expression
11968    is evaluated and compared to each element of the array using the
11969    given <replaceable>operator</replaceable>, which must yield a Boolean
11970    result.
11971    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
11972    The result is <quote>false</> if no true result is found (including the
11973    case where the array has zero elements).
11974   </para>
11975
11976   <para>
11977    If the array expression yields a null array, the result of
11978    <token>ANY</token> will be null.  If the left-hand expression yields null,
11979    the result of <token>ANY</token> is ordinarily null (though a non-strict
11980    comparison operator could possibly yield a different result).
11981    Also, if the right-hand array contains any null elements and no true
11982    comparison result is obtained, the result of <token>ANY</token>
11983    will be null, not false (again, assuming a strict comparison operator).
11984    This is in accordance with SQL's normal rules for Boolean combinations
11985    of null values.
11986   </para>
11987
11988   <para>
11989    <token>SOME</token> is a synonym for <token>ANY</token>.
11990   </para>
11991   </sect2>
11992
11993   <sect2>
11994    <title><literal>ALL</literal> (array)</title>
11995
11996 <synopsis>
11997 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
11998 </synopsis>
11999
12000   <para>
12001    The right-hand side is a parenthesized expression, which must yield an
12002    array value.
12003    The left-hand expression
12004    is evaluated and compared to each element of the array using the
12005    given <replaceable>operator</replaceable>, which must yield a Boolean
12006    result.
12007    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
12008    (including the case where the array has zero elements).
12009    The result is <quote>false</> if any false result is found.
12010   </para>
12011
12012   <para>
12013    If the array expression yields a null array, the result of
12014    <token>ALL</token> will be null.  If the left-hand expression yields null,
12015    the result of <token>ALL</token> is ordinarily null (though a non-strict
12016    comparison operator could possibly yield a different result).
12017    Also, if the right-hand array contains any null elements and no false
12018    comparison result is obtained, the result of <token>ALL</token>
12019    will be null, not true (again, assuming a strict comparison operator).
12020    This is in accordance with SQL's normal rules for Boolean combinations
12021    of null values.
12022   </para>
12023   </sect2>
12024
12025   <sect2 id="row-wise-comparison">
12026    <title>Row-wise Comparison</title>
12027
12028 <synopsis>
12029 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
12030 </synopsis>
12031
12032   <para>
12033    Each side is a row constructor,
12034    as described in <xref linkend="sql-syntax-row-constructors">.
12035    The two row values must have the same number of fields.
12036    Each side is evaluated and they are compared row-wise.  Row comparisons
12037    are allowed when the <replaceable>operator</replaceable> is
12038    <literal>=</>,
12039    <literal>&lt;&gt;</>,
12040    <literal>&lt;</>,
12041    <literal>&lt;=</>,
12042    <literal>&gt;</> or
12043    <literal>&gt;=</>,
12044    or has semantics similar to one of these.  (To be specific, an operator
12045    can be a row comparison operator if it is a member of a B-tree operator
12046    class, or is the negator of the <literal>=</> member of a B-tree operator
12047    class.)
12048   </para>
12049
12050   <para>
12051    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
12052    from the others.  Two rows are considered
12053    equal if all their corresponding members are non-null and equal; the rows
12054    are unequal if any corresponding members are non-null and unequal;
12055    otherwise the result of the row comparison is unknown (null).
12056   </para>
12057
12058   <para>
12059    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
12060    <literal>&gt;=</> cases, the row elements are compared left-to-right,
12061    stopping as soon as an unequal or null pair of elements is found.
12062    If either of this pair of elements is null, the result of the
12063    row comparison is unknown (null); otherwise comparison of this pair
12064    of elements determines the result.  For example,
12065    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
12066    yields true, not null, because the third pair of elements are not
12067    considered.
12068   </para>
12069
12070   <note>
12071    <para>
12072     Prior to <productname>PostgreSQL</productname> 8.2, the
12073     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
12074     cases were not handled per SQL specification.  A comparison like
12075     <literal>ROW(a,b) &lt; ROW(c,d)</>
12076     was implemented as
12077     <literal>a &lt; c AND b &lt; d</>
12078     whereas the correct behavior is equivalent to
12079     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
12080    </para>
12081   </note>
12082
12083 <synopsis>
12084 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
12085 </synopsis>
12086
12087   <para>
12088    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
12089    but it does not yield null for null inputs.  Instead, any null value is
12090    considered unequal to (distinct from) any non-null value, and any two
12091    nulls are considered equal (not distinct).  Thus the result will
12092    either be true or false, never null.
12093   </para>
12094
12095 <synopsis>
12096 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
12097 </synopsis>
12098
12099   <para>
12100    This construct is similar to a <literal>=</literal> row comparison,
12101    but it does not yield null for null inputs.  Instead, any null value is
12102    considered unequal to (distinct from) any non-null value, and any two
12103    nulls are considered equal (not distinct).  Thus the result will always
12104    be either true or false, never null.
12105   </para>
12106
12107   <note>
12108    <para>
12109     The SQL specification requires row-wise comparison to return NULL if the
12110     result depends on comparing two NULL values or a NULL and a non-NULL.
12111     <productname>PostgreSQL</productname> does this only when comparing the
12112     results of two row constructors or comparing a row constructor to the
12113     output of a subquery (as in <xref linkend="functions-subquery">).
12114     In other contexts where two composite-type values are compared, two
12115     NULL field values are considered equal, and a NULL is considered larger
12116     than a non-NULL.  This is necessary in order to have consistent sorting
12117     and indexing behavior for composite types.
12118    </para>
12119   </note>
12120
12121   </sect2>
12122  </sect1>
12123
12124  <sect1 id="functions-srf">
12125   <title>Set Returning Functions</title>
12126
12127   <indexterm zone="functions-srf">
12128    <primary>set returning functions</primary>
12129    <secondary>functions</secondary>
12130   </indexterm>
12131
12132   <indexterm>
12133    <primary>generate_series</primary>
12134   </indexterm>
12135
12136   <para>
12137    This section describes functions that possibly return more than one row.
12138    Currently the only functions in this class are series generating functions,
12139    as detailed in <xref linkend="functions-srf-series"> and
12140    <xref linkend="functions-srf-subscripts">.
12141   </para>
12142
12143   <table id="functions-srf-series">
12144    <title>Series Generating Functions</title>
12145    <tgroup cols="4">
12146     <thead>
12147      <row>
12148       <entry>Function</entry>
12149       <entry>Argument Type</entry>
12150       <entry>Return Type</entry>
12151       <entry>Description</entry>
12152      </row>
12153     </thead>
12154
12155     <tbody>
12156      <row>
12157       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>)</function></literal></entry>
12158       <entry><type>int</type> or <type>bigint</type></entry>
12159       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
12160       <entry>
12161        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
12162        with a step size of one
12163       </entry>
12164      </row>
12165
12166      <row>
12167       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</function></literal></entry>
12168       <entry><type>int</type> or <type>bigint</type></entry>
12169       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
12170       <entry>
12171        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
12172        with a step size of <parameter>step</parameter>
12173       </entry>
12174      </row>
12175
12176      <row>
12177       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</function></literal></entry>
12178       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
12179       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
12180       <entry>
12181        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
12182        with a step size of <parameter>step</parameter>
12183       </entry>
12184      </row>
12185
12186     </tbody>
12187    </tgroup>
12188   </table>
12189
12190   <para>
12191    When <parameter>step</parameter> is positive, zero rows are returned if
12192    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
12193    Conversely, when <parameter>step</parameter> is negative, zero rows are
12194    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
12195    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
12196    for <parameter>step</parameter> to be zero. Some examples follow:
12197 <programlisting>
12198 SELECT * FROM generate_series(2,4);
12199  generate_series
12200 -----------------
12201                2
12202                3
12203                4
12204 (3 rows)
12205
12206 SELECT * FROM generate_series(5,1,-2);
12207  generate_series
12208 -----------------
12209                5
12210                3
12211                1
12212 (3 rows)
12213
12214 SELECT * FROM generate_series(4,3);
12215  generate_series
12216 -----------------
12217 (0 rows)
12218
12219 -- this example relies on the date-plus-integer operator
12220 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
12221    dates
12222 ------------
12223  2004-02-05
12224  2004-02-12
12225  2004-02-19
12226 (3 rows)
12227
12228 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
12229                               '2008-03-04 12:00', '10 hours');
12230    generate_series   
12231 ---------------------
12232  2008-03-01 00:00:00
12233  2008-03-01 10:00:00
12234  2008-03-01 20:00:00
12235  2008-03-02 06:00:00
12236  2008-03-02 16:00:00
12237  2008-03-03 02:00:00
12238  2008-03-03 12:00:00
12239  2008-03-03 22:00:00
12240  2008-03-04 08:00:00
12241 (9 rows)
12242 </programlisting>
12243   </para>
12244
12245   <table id="functions-srf-subscripts">
12246    <title>Subscript Generating Functions</title>
12247    <tgroup cols="3">
12248     <thead>
12249      <row>
12250       <entry>Function</entry>
12251       <entry>Return Type</entry>
12252       <entry>Description</entry>
12253      </row>
12254     </thead>
12255
12256     <tbody>
12257      <row>
12258       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</function></literal></entry>
12259       <entry><type>setof int</type></entry>
12260       <entry>
12261        Generate a series comprising the given array's subscripts.
12262       </entry>
12263      </row>
12264
12265      <row>
12266       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</function></literal></entry>
12267       <entry><type>setof int</type></entry>
12268       <entry>
12269        Generate a series comprising the given array's subscripts. When
12270        <parameter>reverse</parameter> is true, the series is returned in
12271        reverse order.
12272       </entry>
12273      </row>
12274
12275     </tbody>
12276    </tgroup>
12277   </table>
12278
12279   <indexterm>
12280    <primary>generate_subscripts</primary>
12281   </indexterm>
12282
12283   <para>
12284    <function>generate_subscripts</> is a convenience function that generates
12285    the set of valid subscripts for the specified dimension of the given
12286    array.
12287    Zero rows are returned for arrays that do not have the requested dimension,
12288    or for NULL arrays (but valid subscripts are returned for NULL array
12289    elements).  Some examples follow:
12290 <programlisting>
12291 -- basic usage
12292 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
12293  s 
12294 ---
12295  1
12296  2
12297  3
12298  4
12299 (4 rows)
12300
12301 -- presenting an array, the subscript and the subscripted
12302 -- value requires a subquery
12303 SELECT * FROM arrays;
12304          a          
12305 --------------------
12306  {-1,-2}
12307  {100,200,300}
12308 (2 rows)
12309
12310 SELECT a AS array, s AS subscript, a[s] AS value
12311 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
12312      array     | subscript | value
12313 ---------------+-----------+-------
12314  {-1,-2}       |         1 |    -1
12315  {-1,-2}       |         2 |    -2
12316  {100,200,300} |         1 |   100
12317  {100,200,300} |         2 |   200
12318  {100,200,300} |         3 |   300
12319 (5 rows)
12320
12321 -- unnest a 2D array
12322 CREATE OR REPLACE FUNCTION unnest2(anyarray)
12323 RETURNS SETOF anyelement AS $$
12324 select $1[i][j]
12325    from generate_subscripts($1,1) g1(i),
12326         generate_subscripts($1,2) g2(j);
12327 $$ LANGUAGE sql IMMUTABLE;
12328 CREATE FUNCTION
12329 postgres=# SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
12330  unnest2 
12331 ---------
12332        1
12333        2
12334        3
12335        4
12336 (4 rows)
12337 </programlisting>
12338   </para>
12339
12340  </sect1>
12341
12342  <sect1 id="functions-info">
12343   <title>System Information Functions</title>
12344
12345   <para>
12346    <xref linkend="functions-info-session-table"> shows several
12347    functions that extract session and system information.
12348   </para>
12349
12350   <para>
12351    In addition to the functions listed in this section, there are a number of
12352    functions related to the statistics system that also provide system
12353    information. See <xref linkend="monitoring-stats-views"> for more
12354    information.
12355   </para>
12356
12357    <table id="functions-info-session-table">
12358     <title>Session Information Functions</title>
12359     <tgroup cols="3">
12360      <thead>
12361       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12362      </thead>
12363
12364      <tbody>
12365       <row>
12366        <entry><literal><function>current_catalog</function></literal></entry>
12367        <entry><type>name</type></entry>
12368        <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
12369       </row>
12370
12371       <row>
12372        <entry><literal><function>current_database()</function></literal></entry>
12373        <entry><type>name</type></entry>
12374        <entry>name of current database</entry>
12375       </row>
12376
12377       <row>
12378        <entry><literal><function>current_query()</function></literal></entry>
12379        <entry><type>text</type></entry>
12380        <entry>text of the currently executing query, as submitted
12381        by the client (might contain more than one statement)</entry>
12382       </row>
12383
12384       <row>
12385        <entry><literal><function>current_schema</function>[()]</literal></entry>
12386        <entry><type>name</type></entry>
12387        <entry>name of current schema</entry>
12388       </row>
12389
12390       <row>
12391        <entry><literal><function>current_schemas(<type>boolean</type>)</function></literal></entry>
12392        <entry><type>name[]</type></entry>
12393        <entry>names of schemas in search path, optionally including implicit schemas</entry>
12394       </row>
12395
12396       <row>
12397        <entry><literal><function>current_user</function></literal></entry>
12398        <entry><type>name</type></entry>
12399        <entry>user name of current execution context</entry>
12400       </row>
12401
12402       <row>
12403        <entry><literal><function>inet_client_addr()</function></literal></entry>
12404        <entry><type>inet</type></entry>
12405        <entry>address of the remote connection</entry>
12406       </row>
12407
12408       <row>
12409        <entry><literal><function>inet_client_port()</function></literal></entry>
12410        <entry><type>int</type></entry>
12411        <entry>port of the remote connection</entry>
12412       </row>
12413
12414       <row>
12415        <entry><literal><function>inet_server_addr()</function></literal></entry>
12416        <entry><type>inet</type></entry>
12417        <entry>address of the local connection</entry>
12418       </row>
12419
12420       <row>
12421        <entry><literal><function>inet_server_port()</function></literal></entry>
12422        <entry><type>int</type></entry>
12423        <entry>port of the local connection</entry>
12424       </row>
12425
12426       <row>
12427        <!-- See also the entry for this in monitoring.sgml -->
12428        <entry><literal><function>pg_backend_pid()</function></literal></entry>
12429        <entry><type>int</type></entry>
12430        <entry>
12431         Process ID of the server process attached to the current session
12432        </entry>
12433       </row>
12434
12435       <row>
12436        <entry><literal><function>pg_conf_load_time()</function></literal></entry>
12437        <entry><type>timestamp with time zone</type></entry>
12438        <entry>configuration load time</entry>
12439       </row>
12440
12441       <row>
12442        <entry><literal><function>pg_is_other_temp_schema(<type>oid</type>)</function></literal></entry>
12443        <entry><type>boolean</type></entry>
12444        <entry>is schema another session's temporary schema?</entry>
12445       </row>
12446
12447       <row>
12448        <entry><literal><function>pg_listening_channels()</function></literal></entry>
12449        <entry><type>setof text</type></entry>
12450        <entry>channel names that the session is currently listening on</entry>
12451       </row>
12452
12453       <row>
12454        <entry><literal><function>pg_my_temp_schema()</function></literal></entry>
12455        <entry><type>oid</type></entry>
12456        <entry>OID of session's temporary schema, or 0 if none</entry>
12457       </row>
12458
12459       <row>
12460        <entry><literal><function>pg_postmaster_start_time()</function></literal></entry>
12461        <entry><type>timestamp with time zone</type></entry>
12462        <entry>server start time</entry>
12463       </row>
12464
12465       <row>
12466        <entry><literal><function>session_user</function></literal></entry>
12467        <entry><type>name</type></entry>
12468        <entry>session user name</entry>
12469       </row>
12470
12471       <row>
12472        <entry><literal><function>user</function></literal></entry>
12473        <entry><type>name</type></entry>
12474        <entry>equivalent to <function>current_user</function></entry>
12475       </row>
12476
12477       <row>
12478        <entry><literal><function>version()</function></literal></entry>
12479        <entry><type>text</type></entry>
12480        <entry><productname>PostgreSQL</> version information</entry>
12481       </row>
12482      </tbody>
12483     </tgroup>
12484    </table>
12485
12486    <note>
12487     <para>
12488      <function>current_catalog</function>, <function>current_schema</function>,
12489      <function>current_user</function>, <function>session_user</function>,
12490      and <function>user</function> have special syntactic status
12491      in <acronym>SQL</acronym>: they must be called without trailing
12492      parentheses.  (In PostgreSQL, parentheses can optionally be used with
12493      <function>current_schema</function>, but not with the others.)
12494     </para>
12495    </note>
12496
12497    <indexterm>
12498     <primary>current_catalog</primary>
12499    </indexterm>
12500
12501    <indexterm>
12502     <primary>current_database</primary>
12503    </indexterm>
12504
12505    <indexterm>
12506     <primary>current_query</primary>
12507    </indexterm>
12508
12509    <indexterm>
12510     <primary>current_schema</primary>
12511    </indexterm>
12512
12513    <indexterm>
12514     <primary>current_schemas</primary>
12515    </indexterm>
12516
12517    <indexterm>
12518     <primary>current_user</primary>
12519    </indexterm>
12520
12521    <indexterm>
12522     <primary>pg_backend_pid</primary>
12523    </indexterm>
12524
12525    <indexterm>
12526     <primary>schema</primary>
12527     <secondary>current</secondary>
12528    </indexterm>
12529
12530    <indexterm>
12531     <primary>search path</primary>
12532     <secondary>current</secondary>
12533    </indexterm>
12534
12535    <indexterm>
12536     <primary>session_user</primary>
12537    </indexterm>
12538
12539    <indexterm>
12540     <primary>user</primary>
12541     <secondary>current</secondary>
12542    </indexterm>
12543
12544    <indexterm>
12545     <primary>user</primary>
12546    </indexterm>
12547
12548    <para>
12549     The <function>session_user</function> is normally the user who initiated
12550     the current database connection; but superusers can change this setting
12551     with <xref linkend="sql-set-session-authorization">.
12552     The <function>current_user</function> is the user identifier
12553     that is applicable for permission checking. Normally it is equal
12554     to the session user, but it can be changed with
12555     <xref linkend="sql-set-role">.
12556     It also changes during the execution of
12557     functions with the attribute <literal>SECURITY DEFINER</literal>.
12558     In Unix parlance, the session user is the <quote>real user</quote> and
12559     the current user is the <quote>effective user</quote>.
12560    </para>
12561
12562    <para>
12563     <function>current_schema</function> returns the name of the schema that is
12564     first in the search path (or a null value if the search path is
12565     empty).  This is the schema that will be used for any tables or
12566     other named objects that are created without specifying a target schema.
12567     <function>current_schemas(boolean)</function> returns an array of the names of all
12568     schemas presently in the search path.  The Boolean option determines whether or not
12569     implicitly included system schemas such as <literal>pg_catalog</> are included in the
12570     returned search path.
12571    </para>
12572
12573    <note>
12574     <para>
12575      The search path can be altered at run time.  The command is:
12576 <programlisting>
12577 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
12578 </programlisting>
12579     </para>
12580    </note>
12581
12582    <indexterm>
12583     <primary>pg_listening_channels</primary>
12584    </indexterm>
12585
12586    <para>
12587     <function>pg_listening_channels</function> returns a set of names of
12588     channels that the current session is listening to.  See <xref
12589     linkend="sql-listen"> for more information.
12590    </para>
12591
12592    <indexterm>
12593     <primary>inet_client_addr</primary>
12594    </indexterm>
12595
12596    <indexterm>
12597     <primary>inet_client_port</primary>
12598    </indexterm>
12599
12600    <indexterm>
12601     <primary>inet_server_addr</primary>
12602    </indexterm>
12603
12604    <indexterm>
12605     <primary>inet_server_port</primary>
12606    </indexterm>
12607
12608    <para>
12609      <function>inet_client_addr</function> returns the IP address of the
12610      current client, and <function>inet_client_port</function> returns the
12611      port number.
12612      <function>inet_server_addr</function> returns the IP address on which
12613      the server accepted the current connection, and
12614      <function>inet_server_port</function> returns the port number.
12615      All these functions return NULL if the current connection is via a
12616      Unix-domain socket.
12617    </para>
12618
12619    <indexterm>
12620     <primary>pg_my_temp_schema</primary>
12621    </indexterm>
12622
12623    <indexterm>
12624     <primary>pg_is_other_temp_schema</primary>
12625    </indexterm>
12626
12627    <para>
12628     <function>pg_my_temp_schema</function> returns the OID of the current
12629     session's temporary schema, or zero if it has none (because it has not
12630     created any temporary tables).
12631     <function>pg_is_other_temp_schema</function> returns true if the
12632     given OID is the OID of another session's temporary schema.
12633     (This can be useful, for example, to exclude other sessions' temporary
12634     tables from a catalog display.)
12635    </para>
12636
12637    <indexterm>
12638     <primary>pg_postmaster_start_time</primary>
12639    </indexterm>
12640
12641    <para>
12642     <function>pg_postmaster_start_time</function> returns the
12643     <type>timestamp with time zone</type> when the
12644     server started.
12645    </para>
12646
12647    <indexterm>
12648     <primary>pg_conf_load_time</primary>
12649    </indexterm>
12650
12651    <para>
12652     <function>pg_conf_load_time</function> returns the
12653     <type>timestamp with time zone</type> when the
12654     server configuration files were last loaded.
12655     (If the current session was alive at the time, this will be the time
12656     when the session itself re-read the configuration files, so the
12657     reading will vary a little in different sessions.  Otherwise it is
12658     the time when the postmaster process re-read the configuration files.)
12659    </para>
12660
12661    <indexterm>
12662     <primary>version</primary>
12663    </indexterm>
12664
12665    <para>
12666     <function>version</function> returns a string describing the
12667     <productname>PostgreSQL</productname> server's version.
12668    </para>
12669
12670   <indexterm>
12671    <primary>privilege</primary>
12672    <secondary>querying</secondary>
12673   </indexterm>
12674
12675   <para>
12676    <xref linkend="functions-info-access-table"> lists functions that
12677    allow the user to query object access privileges programmatically.
12678    See <xref linkend="ddl-priv"> for more information about
12679    privileges.
12680   </para>
12681
12682    <table id="functions-info-access-table">
12683     <title>Access Privilege Inquiry Functions</title>
12684     <tgroup cols="3">
12685      <thead>
12686       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12687      </thead>
12688
12689      <tbody>
12690       <row>
12691        <entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
12692                                   <parameter>table</parameter>,
12693                                   <parameter>privilege</parameter>)</literal>
12694        </entry>
12695        <entry><type>boolean</type></entry>
12696        <entry>does user have privilege for any column of table</entry>
12697       </row>
12698       <row>
12699        <entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
12700                                   <parameter>privilege</parameter>)</literal>
12701        </entry>
12702        <entry><type>boolean</type></entry>
12703        <entry>does current user have privilege for any column of table</entry>
12704       </row>
12705       <row>
12706        <entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
12707                                   <parameter>table</parameter>,
12708                                   <parameter>column</parameter>,
12709                                   <parameter>privilege</parameter>)</literal>
12710        </entry>
12711        <entry><type>boolean</type></entry>
12712        <entry>does user have privilege for column</entry>
12713       </row>
12714       <row>
12715        <entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
12716                                   <parameter>column</parameter>,
12717                                   <parameter>privilege</parameter>)</literal>
12718        </entry>
12719        <entry><type>boolean</type></entry>
12720        <entry>does current user have privilege for column</entry>
12721       </row>
12722       <row>
12723        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
12724                                   <parameter>database</parameter>,
12725                                   <parameter>privilege</parameter>)</literal>
12726        </entry>
12727        <entry><type>boolean</type></entry>
12728        <entry>does user have privilege for database</entry>
12729       </row>
12730       <row>
12731        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
12732                                   <parameter>privilege</parameter>)</literal>
12733        </entry>
12734        <entry><type>boolean</type></entry>
12735        <entry>does current user have privilege for database</entry>
12736       </row>
12737       <row>
12738        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
12739                                   <parameter>fdw</parameter>,
12740                                   <parameter>privilege</parameter>)</literal>
12741        </entry>
12742        <entry><type>boolean</type></entry>
12743        <entry>does user have privilege for foreign-data wrapper</entry>
12744       </row>
12745       <row>
12746        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
12747                                   <parameter>privilege</parameter>)</literal>
12748        </entry>
12749        <entry><type>boolean</type></entry>
12750        <entry>does current user have privilege for foreign-data wrapper</entry>
12751       </row>
12752       <row>
12753        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
12754                                   <parameter>function</parameter>,
12755                                   <parameter>privilege</parameter>)</literal>
12756        </entry>
12757        <entry><type>boolean</type></entry>
12758        <entry>does user have privilege for function</entry>
12759       </row>
12760       <row>
12761        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
12762                                   <parameter>privilege</parameter>)</literal>
12763        </entry>
12764        <entry><type>boolean</type></entry>
12765        <entry>does current user have privilege for function</entry>
12766       </row>
12767       <row>
12768        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
12769                                   <parameter>language</parameter>,
12770                                   <parameter>privilege</parameter>)</literal>
12771        </entry>
12772        <entry><type>boolean</type></entry>
12773        <entry>does user have privilege for language</entry>
12774       </row>
12775       <row>
12776        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
12777                                   <parameter>privilege</parameter>)</literal>
12778        </entry>
12779        <entry><type>boolean</type></entry>
12780        <entry>does current user have privilege for language</entry>
12781       </row>
12782       <row>
12783        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
12784                                   <parameter>schema</parameter>,
12785                                   <parameter>privilege</parameter>)</literal>
12786        </entry>
12787        <entry><type>boolean</type></entry>
12788        <entry>does user have privilege for schema</entry>
12789       </row>
12790       <row>
12791        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
12792                                   <parameter>privilege</parameter>)</literal>
12793        </entry>
12794        <entry><type>boolean</type></entry>
12795        <entry>does current user have privilege for schema</entry>
12796       </row>
12797       <row>
12798        <entry><literal><function>has_sequence_privilege</function>(<parameter>user</parameter>,
12799                                   <parameter>sequence</parameter>,
12800                                   <parameter>privilege</parameter>)</literal>
12801        </entry>
12802        <entry><type>boolean</type></entry>
12803        <entry>does user have privilege for sequence</entry>
12804       </row>
12805       <row>
12806        <entry><literal><function>has_sequence_privilege</function>(<parameter>sequence</parameter>,
12807                                   <parameter>privilege</parameter>)</literal>
12808        </entry>
12809        <entry><type>boolean</type></entry>
12810        <entry>does current user have privilege for sequence</entry>
12811       </row>
12812       <row>
12813        <entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
12814                                   <parameter>server</parameter>,
12815                                   <parameter>privilege</parameter>)</literal>
12816        </entry>
12817        <entry><type>boolean</type></entry>
12818        <entry>does user have privilege for foreign server</entry>
12819       </row>
12820       <row>
12821        <entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
12822                                   <parameter>privilege</parameter>)</literal>
12823        </entry>
12824        <entry><type>boolean</type></entry>
12825        <entry>does current user have privilege for foreign server</entry>
12826       </row>
12827       <row>
12828        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
12829                                   <parameter>table</parameter>,
12830                                   <parameter>privilege</parameter>)</literal>
12831        </entry>
12832        <entry><type>boolean</type></entry>
12833        <entry>does user have privilege for table</entry>
12834       </row>
12835       <row>
12836        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
12837                                   <parameter>privilege</parameter>)</literal>
12838        </entry>
12839        <entry><type>boolean</type></entry>
12840        <entry>does current user have privilege for table</entry>
12841       </row>
12842       <row>
12843        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
12844                                   <parameter>tablespace</parameter>,
12845                                   <parameter>privilege</parameter>)</literal>
12846        </entry>
12847        <entry><type>boolean</type></entry>
12848        <entry>does user have privilege for tablespace</entry>
12849       </row>
12850       <row>
12851        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
12852                                   <parameter>privilege</parameter>)</literal>
12853        </entry>
12854        <entry><type>boolean</type></entry>
12855        <entry>does current user have privilege for tablespace</entry>
12856       </row>
12857       <row>
12858        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
12859                                   <parameter>role</parameter>,
12860                                   <parameter>privilege</parameter>)</literal>
12861        </entry>
12862        <entry><type>boolean</type></entry>
12863        <entry>does user have privilege for role</entry>
12864       </row>
12865       <row>
12866        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
12867                                   <parameter>privilege</parameter>)</literal>
12868        </entry>
12869        <entry><type>boolean</type></entry>
12870        <entry>does current user have privilege for role</entry>
12871       </row>
12872      </tbody>
12873     </tgroup>
12874    </table>
12875
12876    <indexterm>
12877     <primary>has_any_column_privilege</primary>
12878    </indexterm>
12879    <indexterm>
12880     <primary>has_column_privilege</primary>
12881    </indexterm>
12882    <indexterm>
12883     <primary>has_database_privilege</primary>
12884    </indexterm>
12885    <indexterm>
12886     <primary>has_function_privilege</primary>
12887    </indexterm>
12888    <indexterm>
12889     <primary>has_foreign_data_wrapper_privilege</primary>
12890    </indexterm>
12891    <indexterm>
12892     <primary>has_language_privilege</primary>
12893    </indexterm>
12894    <indexterm>
12895     <primary>has_schema_privilege</primary>
12896    </indexterm>
12897    <indexterm>
12898     <primary>has_server_privilege</primary>
12899    </indexterm>
12900    <indexterm>
12901     <primary>has_sequence_privilege</primary>
12902    </indexterm>
12903    <indexterm>
12904     <primary>has_table_privilege</primary>
12905    </indexterm>
12906    <indexterm>
12907     <primary>has_tablespace_privilege</primary>
12908    </indexterm>
12909    <indexterm>
12910     <primary>pg_has_role</primary>
12911    </indexterm>
12912
12913    <para>
12914     <function>has_table_privilege</function> checks whether a user
12915     can access a table in a particular way.  The user can be
12916     specified by name, by OID (<literal>pg_authid.oid</literal>),
12917     <literal>public</> to indicate the PUBLIC pseudo-role, or if the argument is
12918     omitted
12919     <function>current_user</function> is assumed.  The table can be specified
12920     by name or by OID.  (Thus, there are actually six variants of
12921     <function>has_table_privilege</function>, which can be distinguished by
12922     the number and types of their arguments.)  When specifying by name,
12923     the name can be schema-qualified if necessary.
12924     The desired access privilege type
12925     is specified by a text string, which must evaluate to one of the
12926     values <literal>SELECT</literal>, <literal>INSERT</literal>,
12927     <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
12928     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.  Optionally,
12929     <literal>WITH GRANT OPTION</> can be added to a privilege type to test
12930     whether the privilege is held with grant option.  Also, multiple privilege
12931     types can be listed separated by commas, in which case the result will
12932     be <literal>true</> if any of the listed privileges is held.
12933     (Case of the privilege string is not significant, and extra whitespace
12934     is allowed between but not within privilege names.)
12935     Some examples:
12936 <programlisting>
12937 SELECT has_table_privilege('myschema.mytable', 'select');
12938 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
12939 </programlisting>
12940    </para>
12941
12942    <para>
12943     <function>has_sequence_privilege</function> checks whether a user
12944     can access a sequence in a particular way.  The possibilities for its
12945     arguments are analogous to <function>has_table_privilege</function>.
12946     The desired access privilege type must evaluate to one of
12947     <literal>USAGE</literal>,
12948     <literal>SELECT</literal>, or
12949     <literal>UPDATE</literal>.
12950    </para>
12951
12952    <para>
12953     <function>has_any_column_privilege</function> checks whether a user can
12954     access any column of a table in a particular way.
12955     Its argument possibilities
12956     are analogous to <function>has_table_privilege</>,
12957     except that the desired access privilege type must evaluate to some
12958     combination of
12959     <literal>SELECT</literal>,
12960     <literal>INSERT</literal>,
12961     <literal>UPDATE</literal>, or
12962     <literal>REFERENCES</literal>.  Note that having any of these privileges
12963     at the table level implicitly grants it for each column of the table,
12964     so <function>has_any_column_privilege</function> will always return
12965     <literal>true</> if <function>has_table_privilege</> does for the same
12966     arguments.  But <function>has_any_column_privilege</> also succeeds if
12967     there is a column-level grant of the privilege for at least one column.
12968    </para>
12969
12970    <para>
12971     <function>has_column_privilege</function> checks whether a user
12972     can access a column in a particular way.
12973     Its argument possibilities
12974     are analogous to <function>has_table_privilege</function>,
12975     with the addition that the column can be specified either by name
12976     or attribute number.
12977     The desired access privilege type must evaluate to some combination of
12978     <literal>SELECT</literal>,
12979     <literal>INSERT</literal>,
12980     <literal>UPDATE</literal>, or
12981     <literal>REFERENCES</literal>.  Note that having any of these privileges
12982     at the table level implicitly grants it for each column of the table.
12983    </para>
12984
12985    <para>
12986     <function>has_database_privilege</function> checks whether a user
12987     can access a database in a particular way.
12988     Its argument possibilities
12989     are analogous to <function>has_table_privilege</function>.
12990     The desired access privilege type must evaluate to some combination of
12991     <literal>CREATE</literal>,
12992     <literal>CONNECT</literal>,
12993     <literal>TEMPORARY</literal>, or
12994     <literal>TEMP</literal> (which is equivalent to
12995     <literal>TEMPORARY</literal>).
12996    </para>
12997
12998    <para>
12999     <function>has_function_privilege</function> checks whether a user
13000     can access a function in a particular way.
13001     Its argument possibilities
13002     are analogous to <function>has_table_privilege</function>.
13003     When specifying a function by a text string rather than by OID,
13004     the allowed input is the same as for the <type>regprocedure</> data type
13005     (see <xref linkend="datatype-oid">).
13006     The desired access privilege type must evaluate to
13007     <literal>EXECUTE</literal>.
13008     An example is:
13009 <programlisting>
13010 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
13011 </programlisting>
13012    </para>
13013
13014    <para>
13015     <function>has_foreign_data_wrapper_privilege</function> checks whether a user
13016     can access a foreign-data wrapper in a particular way.
13017     Its argument possibilities
13018     are analogous to <function>has_table_privilege</function>.
13019     The desired access privilege type must evaluate to
13020     <literal>USAGE</literal>.
13021    </para>
13022
13023    <para>
13024     <function>has_language_privilege</function> checks whether a user
13025     can access a procedural language in a particular way.
13026     Its argument possibilities
13027     are analogous to <function>has_table_privilege</function>.
13028     The desired access privilege type must evaluate to
13029     <literal>USAGE</literal>.
13030    </para>
13031
13032    <para>
13033     <function>has_schema_privilege</function> checks whether a user
13034     can access a schema in a particular way.
13035     Its argument possibilities
13036     are analogous to <function>has_table_privilege</function>.
13037     The desired access privilege type must evaluate to some combination of
13038     <literal>CREATE</literal> or
13039     <literal>USAGE</literal>.
13040    </para>
13041
13042    <para>
13043     <function>has_server_privilege</function> checks whether a user
13044     can access a foreign server in a particular way.
13045     Its argument possibilities
13046     are analogous to <function>has_table_privilege</function>.
13047     The desired access privilege type must evaluate to
13048     <literal>USAGE</literal>.
13049    </para>
13050
13051    <para>
13052     <function>has_tablespace_privilege</function> checks whether a user
13053     can access a tablespace in a particular way.
13054     Its argument possibilities
13055     are analogous to <function>has_table_privilege</function>.
13056     The desired access privilege type must evaluate to
13057     <literal>CREATE</literal>.
13058    </para>
13059
13060    <para>
13061     <function>pg_has_role</function> checks whether a user
13062     can access a role in a particular way.
13063     Its argument possibilities
13064     are analogous to <function>has_table_privilege</function>,
13065     except that <literal>public</> is not allowed as a user name.
13066     The desired access privilege type must evaluate to some combination of
13067     <literal>MEMBER</literal> or
13068     <literal>USAGE</literal>.
13069     <literal>MEMBER</literal> denotes direct or indirect membership in
13070     the role (that is, the right to do <command>SET ROLE</>), while
13071     <literal>USAGE</literal> denotes whether the privileges of the role
13072     are immediately available without doing <command>SET ROLE</>.
13073    </para>
13074
13075   <para>
13076    <xref linkend="functions-info-schema-table"> shows functions that
13077    determine whether a certain object is <firstterm>visible</> in the
13078    current schema search path.
13079    For example, a table is said to be visible if its
13080    containing schema is in the search path and no table of the same
13081    name appears earlier in the search path.  This is equivalent to the
13082    statement that the table can be referenced by name without explicit
13083    schema qualification.  To list the names of all visible tables:
13084 <programlisting>
13085 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
13086 </programlisting>
13087   </para>
13088
13089    <table id="functions-info-schema-table">
13090     <title>Schema Visibility Inquiry Functions</title>
13091     <tgroup cols="3">
13092      <thead>
13093       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13094      </thead>
13095
13096      <tbody>
13097       <row>
13098        <entry><literal><function>pg_collation_is_visible(<parameter>collation_oid</parameter>)</function></literal>
13099        </entry>
13100        <entry><type>boolean</type></entry>
13101        <entry>is collation visible in search path</entry>
13102       </row>
13103       <row>
13104        <entry><literal><function>pg_conversion_is_visible(<parameter>conversion_oid</parameter>)</function></literal>
13105        </entry>
13106        <entry><type>boolean</type></entry>
13107        <entry>is conversion visible in search path</entry>
13108       </row>
13109       <row>
13110        <entry><literal><function>pg_function_is_visible(<parameter>function_oid</parameter>)</function></literal>
13111        </entry>
13112        <entry><type>boolean</type></entry>
13113        <entry>is function visible in search path</entry>
13114       </row>
13115       <row>
13116        <entry><literal><function>pg_opclass_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
13117        </entry>
13118        <entry><type>boolean</type></entry>
13119        <entry>is operator class visible in search path</entry>
13120       </row>
13121       <row>
13122        <entry><literal><function>pg_operator_is_visible(<parameter>operator_oid</parameter>)</function></literal>
13123        </entry>
13124        <entry><type>boolean</type></entry>
13125        <entry>is operator visible in search path</entry>
13126       </row>
13127       <row>
13128        <entry><literal><function>pg_opfamily_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
13129        </entry>
13130        <entry><type>boolean</type></entry>
13131        <entry>is operator family visible in search path</entry>
13132       </row>
13133       <row>
13134        <entry><literal><function>pg_table_is_visible(<parameter>table_oid</parameter>)</function></literal>
13135        </entry>
13136        <entry><type>boolean</type></entry>
13137        <entry>is table visible in search path</entry>
13138       </row>
13139       <row>
13140        <entry><literal><function>pg_ts_config_is_visible(<parameter>config_oid</parameter>)</function></literal>
13141        </entry>
13142        <entry><type>boolean</type></entry>
13143        <entry>is text search configuration visible in search path</entry>
13144       </row>
13145       <row>
13146        <entry><literal><function>pg_ts_dict_is_visible(<parameter>dict_oid</parameter>)</function></literal>
13147        </entry>
13148        <entry><type>boolean</type></entry>
13149        <entry>is text search dictionary visible in search path</entry>
13150       </row>
13151       <row>
13152        <entry><literal><function>pg_ts_parser_is_visible(<parameter>parser_oid</parameter>)</function></literal>
13153        </entry>
13154        <entry><type>boolean</type></entry>
13155        <entry>is text search parser visible in search path</entry>
13156       </row>
13157       <row>
13158        <entry><literal><function>pg_ts_template_is_visible(<parameter>template_oid</parameter>)</function></literal>
13159        </entry>
13160        <entry><type>boolean</type></entry>
13161        <entry>is text search template visible in search path</entry>
13162       </row>
13163       <row>
13164        <entry><literal><function>pg_type_is_visible(<parameter>type_oid</parameter>)</function></literal>
13165        </entry>
13166        <entry><type>boolean</type></entry>
13167        <entry>is type (or domain) visible in search path</entry>
13168       </row>
13169      </tbody>
13170     </tgroup>
13171    </table>
13172
13173    <indexterm>
13174     <primary>pg_collation_is_visible</primary>
13175    </indexterm>
13176    <indexterm>
13177     <primary>pg_conversion_is_visible</primary>
13178    </indexterm>
13179    <indexterm>
13180     <primary>pg_function_is_visible</primary>
13181    </indexterm>
13182    <indexterm>
13183     <primary>pg_opclass_is_visible</primary>
13184    </indexterm>
13185    <indexterm>
13186     <primary>pg_operator_is_visible</primary>
13187    </indexterm>
13188    <indexterm>
13189     <primary>pg_opfamily_is_visible</primary>
13190    </indexterm>
13191    <indexterm>
13192     <primary>pg_table_is_visible</primary>
13193    </indexterm>
13194    <indexterm>
13195     <primary>pg_ts_config_is_visible</primary>
13196    </indexterm>
13197    <indexterm>
13198     <primary>pg_ts_dict_is_visible</primary>
13199    </indexterm>
13200    <indexterm>
13201     <primary>pg_ts_parser_is_visible</primary>
13202    </indexterm>
13203    <indexterm>
13204     <primary>pg_ts_template_is_visible</primary>
13205    </indexterm>
13206    <indexterm>
13207     <primary>pg_type_is_visible</primary>
13208    </indexterm>
13209
13210    <para>
13211     Each function performs the visibility check for one type of database
13212     object.  Note that <function>pg_table_is_visible</function> can also be used
13213     with views, indexes and sequences; <function>pg_type_is_visible</function>
13214     can also be used with domains. For functions and operators, an object in
13215     the search path is visible if there is no object of the same name
13216     <emphasis>and argument data type(s)</> earlier in the path.  For operator
13217     classes, both name and associated index access method are considered.
13218    </para>
13219
13220    <para>
13221     All these functions require object OIDs to identify the object to be
13222     checked.  If you want to test an object by name, it is convenient to use
13223     the OID alias types (<type>regclass</>, <type>regtype</>,
13224     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
13225     or <type>regdictionary</>),
13226     for example:
13227 <programlisting>
13228 SELECT pg_type_is_visible('myschema.widget'::regtype);
13229 </programlisting>
13230     Note that it would not make much sense to test a non-schema-qualified
13231     type name in this way &mdash; if the name can be recognized at all, it must be visible.
13232    </para>
13233
13234    <indexterm>
13235     <primary>format_type</primary>
13236    </indexterm>
13237
13238    <indexterm>
13239     <primary>pg_describe_object</primary>
13240    </indexterm>
13241
13242    <indexterm>
13243     <primary>pg_get_constraintdef</primary>
13244    </indexterm>
13245
13246    <indexterm>
13247     <primary>pg_get_expr</primary>
13248    </indexterm>
13249
13250    <indexterm>
13251     <primary>pg_get_functiondef</primary>
13252    </indexterm>
13253
13254    <indexterm>
13255     <primary>pg_get_function_arguments</primary>
13256    </indexterm>
13257
13258    <indexterm>
13259     <primary>pg_get_function_identity_arguments</primary>
13260    </indexterm>
13261
13262    <indexterm>
13263     <primary>pg_get_function_result</primary>
13264    </indexterm>
13265
13266    <indexterm>
13267     <primary>pg_get_indexdef</primary>
13268    </indexterm>
13269
13270    <indexterm>
13271     <primary>pg_get_keywords</primary>
13272    </indexterm>
13273
13274    <indexterm>
13275     <primary>pg_get_ruledef</primary>
13276    </indexterm>
13277
13278    <indexterm>
13279     <primary>pg_get_serial_sequence</primary>
13280    </indexterm>
13281
13282    <indexterm>
13283     <primary>pg_get_triggerdef</primary>
13284    </indexterm>
13285
13286    <indexterm>
13287     <primary>pg_get_userbyid</primary>
13288    </indexterm>
13289
13290    <indexterm>
13291     <primary>pg_get_viewdef</primary>
13292    </indexterm>
13293
13294    <indexterm>
13295     <primary>pg_options_to_table</primary>
13296    </indexterm>
13297
13298    <indexterm>
13299     <primary>pg_tablespace_databases</primary>
13300    </indexterm>
13301
13302    <indexterm>
13303     <primary>pg_typeof</primary>
13304    </indexterm>
13305
13306   <para>
13307    <xref linkend="functions-info-catalog-table"> lists functions that
13308    extract information from the system catalogs.
13309   </para>
13310
13311    <table id="functions-info-catalog-table">
13312     <title>System Catalog Information Functions</title>
13313     <tgroup cols="3">
13314      <thead>
13315       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13316      </thead>
13317
13318      <tbody>
13319       <row>
13320        <entry><literal><function>format_type(<parameter>type_oid</parameter>, <parameter>typemod</>)</function></literal></entry>
13321        <entry><type>text</type></entry>
13322        <entry>get SQL name of a data type</entry>
13323       </row>
13324       <row>
13325        <entry><literal><function>pg_describe_object(<parameter>catalog_id</parameter>, <parameter>object_id</parameter>, <parameter>object_sub_id</parameter>)</function></literal></entry>
13326        <entry><type>text</type></entry>
13327        <entry>get description of a database object</entry>
13328       </row>
13329       <row>
13330        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>)</function></literal></entry>
13331        <entry><type>text</type></entry>
13332        <entry>get definition of a constraint</entry>
13333       </row>
13334       <row>
13335        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13336        <entry><type>text</type></entry>
13337        <entry>get definition of a constraint</entry>
13338       </row>
13339       <row>
13340        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>)</function></literal></entry>
13341        <entry><type>text</type></entry>
13342        <entry>decompile internal form of an expression, assuming that any Vars
13343        in it refer to the relation indicated by the second parameter</entry>
13344       </row>
13345       <row>
13346        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</function></literal></entry>
13347        <entry><type>text</type></entry>
13348        <entry>decompile internal form of an expression, assuming that any Vars
13349        in it refer to the relation indicated by the second parameter</entry>
13350       </row>
13351       <row>
13352        <entry><literal><function>pg_get_functiondef(<parameter>func_oid</parameter>)</function></literal></entry>
13353        <entry><type>text</type></entry>
13354        <entry>get definition of a function</entry>
13355       </row>
13356       <row>
13357        <entry><literal><function>pg_get_function_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
13358        <entry><type>text</type></entry>
13359        <entry>get argument list of function's definition (with default values)</entry>
13360       </row>
13361       <row>
13362        <entry><literal><function>pg_get_function_identity_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
13363        <entry><type>text</type></entry>
13364        <entry>get argument list to identify a function (without default values)</entry>
13365       </row>
13366       <row>
13367        <entry><literal><function>pg_get_function_result(<parameter>func_oid</parameter>)</function></literal></entry>
13368        <entry><type>text</type></entry>
13369        <entry>get <literal>RETURNS</> clause for function</entry>
13370       </row>
13371       <row>
13372        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>)</function></literal></entry>
13373        <entry><type>text</type></entry>
13374        <entry>get <command>CREATE INDEX</> command for index</entry>
13375       </row>
13376       <row>
13377        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</function></literal></entry>
13378        <entry><type>text</type></entry>
13379        <entry>get <command>CREATE INDEX</> command for index,
13380        or definition of just one index column when
13381        <parameter>column_no</> is not zero</entry>
13382       </row>
13383       <row>
13384        <entry><literal><function>pg_get_keywords()</function></literal></entry>
13385        <entry><type>setof record</type></entry>
13386        <entry>get list of SQL keywords and their categories</entry>
13387       </row>
13388       <row>
13389        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>)</function></literal></entry>
13390        <entry><type>text</type></entry>
13391        <entry>get <command>CREATE RULE</> command for rule</entry>
13392       </row>
13393       <row>
13394        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13395        <entry><type>text</type></entry>
13396        <entry>get <command>CREATE RULE</> command for rule</entry>
13397       </row>
13398       <row>
13399        <entry><literal><function>pg_get_serial_sequence(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</function></literal></entry>
13400        <entry><type>text</type></entry>
13401        <entry>get name of the sequence that a <type>serial</type>, <type>smallserial</type> or <type>bigserial</type> column
13402        uses</entry>
13403       </row>
13404       <row>
13405        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
13406        <entry><type>text</type></entry>
13407        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
13408       </row>
13409       <row>
13410        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>, <parameter>pretty_bool</>)</entry>
13411        <entry><type>text</type></entry>
13412        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
13413       </row>
13414       <row>
13415        <entry><literal><function>pg_get_userbyid(<parameter>role_oid</parameter>)</function></literal></entry>
13416        <entry><type>name</type></entry>
13417        <entry>get role name with given OID</entry>
13418       </row>
13419       <row>
13420        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>)</function></literal></entry>
13421        <entry><type>text</type></entry>
13422        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
13423       </row>
13424       <row>
13425        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13426        <entry><type>text</type></entry>
13427        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
13428       </row>
13429       <row>
13430        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>)</function></literal></entry>
13431        <entry><type>text</type></entry>
13432        <entry>get underlying <command>SELECT</command> command for view</entry>
13433       </row>
13434       <row>
13435        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13436        <entry><type>text</type></entry>
13437        <entry>get underlying <command>SELECT</command> command for view</entry>
13438       </row>
13439       <row>
13440        <entry><literal><function>pg_options_to_table(<parameter>reloptions</parameter>)</function></literal></entry>
13441        <entry><type>setof record</type></entry>
13442        <entry>get the set of storage option name/value pairs</entry>
13443       </row>
13444       <row>
13445        <entry><literal><function>pg_tablespace_databases(<parameter>tablespace_oid</parameter>)</function></literal></entry>
13446        <entry><type>setof oid</type></entry>
13447        <entry>get the set of database OIDs that have objects in the tablespace</entry>
13448       </row>
13449       <row>
13450        <entry><literal><function>pg_typeof(<parameter>any</parameter>)</function></literal></entry>
13451        <entry><type>regtype</type></entry>
13452        <entry>get the data type of any value</entry>
13453       </row>
13454      </tbody>
13455     </tgroup>
13456    </table>
13457
13458   <para>
13459    <function>format_type</function> returns the SQL name of a data type that
13460    is identified by its type OID and possibly a type modifier.  Pass NULL
13461    for the type modifier if no specific modifier is known.
13462   </para>
13463
13464   <para>
13465    <function>pg_get_keywords</function> returns a set of records describing
13466    the SQL keywords recognized by the server. The <structfield>word</> column
13467    contains the keyword.  The <structfield>catcode</> column contains a
13468    category code: <literal>U</> for unreserved, <literal>C</> for column name,
13469    <literal>T</> for type or function name, or <literal>R</> for reserved.
13470    The <structfield>catdesc</> column contains a possibly-localized string
13471    describing the category.
13472   </para>
13473
13474   <para>
13475    <function>pg_get_constraintdef</function>,
13476    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
13477    and <function>pg_get_triggerdef</function>, respectively reconstruct the
13478    creating command for a constraint, index, rule, or trigger. (Note that this
13479    is a decompiled reconstruction, not the original text of the command.)
13480    <function>pg_get_expr</function> decompiles the internal form of an
13481    individual expression, such as the default value for a column.  It can be
13482    useful when examining the contents of system catalogs.  If the expression
13483    might contain Vars, specify the OID of the relation they refer to as the
13484    second parameter; if no Vars are expected, zero is sufficient.
13485    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
13486    query that defines a view. Most of these functions come in two variants,
13487    one of which can optionally <quote>pretty-print</> the result.  The
13488    pretty-printed format is more readable, but the default format is more
13489    likely to be interpreted the same way by future versions of
13490    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
13491    purposes.  Passing <literal>false</> for the pretty-print parameter yields
13492    the same result as the variant that does not have the parameter at all.
13493   </para>
13494
13495   <para>
13496    <function>pg_get_functiondef</> returns a complete
13497    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
13498    <function>pg_get_function_arguments</function> returns the argument list
13499    of a function, in the form it would need to appear in within
13500    <command>CREATE FUNCTION</>.
13501    <function>pg_get_function_result</function> similarly returns the
13502    appropriate <literal>RETURNS</> clause for the function.
13503    <function>pg_get_function_identity_arguments</function> returns the
13504    argument list necessary to identify a function, in the form it
13505    would need to appear in within <command>ALTER FUNCTION</>, for
13506    instance.  This form omits default values.
13507   </para>
13508
13509   <para>
13510    <function>pg_get_serial_sequence</function> returns the name of the
13511    sequence associated with a column, or NULL if no sequence is associated
13512    with the column.  The first input parameter is a table name with
13513    optional schema, and the second parameter is a column name.  Because
13514    the first parameter is potentially a schema and table, it is not treated
13515    as a double-quoted identifier, meaning it is lower cased by default,
13516    while the second parameter, being just a column name, is treated as
13517    double-quoted and has its case preserved.  The function returns a value
13518    suitably formatted for passing to sequence functions (see <xref
13519    linkend="functions-sequence">).  This association can be modified or
13520    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
13521    probably should have been called
13522    <function>pg_get_owned_sequence</function>; its current name reflects the fact
13523    that it's typically used with <type>serial</> or <type>bigserial</>
13524    columns.)
13525   </para>
13526
13527   <para>
13528    <function>pg_get_userbyid</function> extracts a role's name given
13529    its OID.
13530   </para>
13531
13532   <para>
13533    <function>pg_options_to_table</function> returns the set of storage
13534    option name/value pairs
13535    (<literal>option_name</>/<literal>option_value</>) when passed
13536    <structname>pg_class</>.<structfield>reloptions</> or
13537    <structname>pg_attribute</>.<structfield>attoptions</>.
13538   </para>
13539
13540   <para>
13541    <function>pg_tablespace_databases</function> allows a tablespace to be
13542    examined. It returns the set of OIDs of databases that have objects stored
13543    in the tablespace. If this function returns any rows, the tablespace is not
13544    empty and cannot be dropped. To display the specific objects populating the
13545    tablespace, you will need to connect to the databases identified by
13546    <function>pg_tablespace_databases</function> and query their
13547    <structname>pg_class</> catalogs.
13548   </para>
13549
13550   <para>
13551    <function>pg_describe_object</function> returns a description of a database
13552    object specified by catalog OID, object OID and a (possibly zero) sub-object ID.
13553    This is useful to determine the identity of an object as stored in the
13554    <structname>pg_depend</structname> catalog.
13555   </para>
13556
13557   <para>
13558    <function>pg_typeof</function> returns the OID of the data type of the
13559    value that is passed to it.  This can be helpful for troubleshooting or
13560    dynamically constructing SQL queries.  The function is declared as
13561    returning <type>regtype</>, which is an OID alias type (see
13562    <xref linkend="datatype-oid">); this means that it is the same as an
13563    OID for comparison purposes but displays as a type name.  For example:
13564 <programlisting>
13565 SELECT pg_typeof(33);
13566
13567  pg_typeof 
13568 -----------
13569  integer
13570 (1 row)
13571
13572 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
13573  typlen 
13574 --------
13575       4
13576 (1 row)
13577 </programlisting>
13578   </para>
13579
13580    <indexterm>
13581     <primary>col_description</primary>
13582    </indexterm>
13583
13584    <indexterm>
13585     <primary>obj_description</primary>
13586    </indexterm>
13587
13588    <indexterm>
13589     <primary>shobj_description</primary>
13590    </indexterm>
13591
13592    <indexterm>
13593     <primary>comment</primary>
13594     <secondary sortas="database objects">about database objects</secondary>
13595    </indexterm>
13596
13597    <para>
13598     The functions shown in <xref linkend="functions-info-comment-table">
13599     extract comments previously stored with the <xref linkend="sql-comment">
13600     command.  A null value is returned if no
13601     comment could be found for the specified parameters.
13602    </para>
13603
13604    <table id="functions-info-comment-table">
13605     <title>Comment Information Functions</title>
13606     <tgroup cols="3">
13607      <thead>
13608       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13609      </thead>
13610
13611      <tbody>
13612       <row>
13613        <entry><literal><function>col_description(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</function></literal></entry>
13614        <entry><type>text</type></entry>
13615        <entry>get comment for a table column</entry>
13616       </row>
13617       <row>
13618        <entry><literal><function>obj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
13619        <entry><type>text</type></entry>
13620        <entry>get comment for a database object</entry>
13621       </row>
13622       <row>
13623        <entry><literal><function>obj_description(<parameter>object_oid</parameter>)</function></literal></entry>
13624        <entry><type>text</type></entry>
13625        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
13626       </row>
13627       <row>
13628        <entry><literal><function>shobj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
13629        <entry><type>text</type></entry>
13630        <entry>get comment for a shared database object</entry>
13631       </row>
13632      </tbody>
13633     </tgroup>
13634    </table>
13635
13636    <para>
13637     <function>col_description</function> returns the comment for a table
13638     column, which is specified by the OID of its table and its column number.
13639     (<function>obj_description</function> cannot be used for table columns
13640     since columns do not have OIDs of their own.)
13641    </para>
13642
13643    <para>
13644     The two-parameter form of <function>obj_description</function> returns the
13645     comment for a database object specified by its OID and the name of the
13646     containing system catalog.  For example,
13647     <literal>obj_description(123456,'pg_class')</literal>
13648     would retrieve the comment for the table with OID 123456.
13649     The one-parameter form of <function>obj_description</function> requires only
13650     the object OID.  It is deprecated since there is no guarantee that
13651     OIDs are unique across different system catalogs; therefore, the wrong
13652     comment might be returned.
13653    </para>
13654
13655    <para>
13656     <function>shobj_description</function> is used just like
13657     <function>obj_description</function> except it is used for retrieving
13658     comments on shared objects.  Some system catalogs are global to all
13659     databases within each cluster, and the descriptions for objects in them
13660     are stored globally as well.
13661    </para>
13662
13663    <indexterm>
13664     <primary>txid_current</primary>
13665    </indexterm>
13666
13667    <indexterm>
13668     <primary>txid_current_snapshot</primary>
13669    </indexterm>
13670
13671    <indexterm>
13672     <primary>txid_snapshot_xip</primary>
13673    </indexterm>
13674
13675    <indexterm>
13676     <primary>txid_snapshot_xmax</primary>
13677    </indexterm>
13678
13679    <indexterm>
13680     <primary>txid_snapshot_xmin</primary>
13681    </indexterm>
13682
13683    <indexterm>
13684     <primary>txid_visible_in_snapshot</primary>
13685    </indexterm>
13686
13687    <para>
13688     The functions shown in <xref linkend="functions-txid-snapshot">
13689     provide server transaction information in an exportable form.  The main
13690     use of these functions is to determine which transactions were committed
13691     between two snapshots.
13692    </para>
13693
13694    <table id="functions-txid-snapshot">
13695     <title>Transaction IDs and Snapshots</title>
13696     <tgroup cols="3">
13697      <thead>
13698       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13699      </thead>
13700
13701      <tbody>
13702       <row>
13703        <entry><literal><function>txid_current()</function></literal></entry>
13704        <entry><type>bigint</type></entry>
13705        <entry>get current transaction ID</entry>
13706       </row>
13707       <row>
13708        <entry><literal><function>txid_current_snapshot()</function></literal></entry>
13709        <entry><type>txid_snapshot</type></entry>
13710        <entry>get current snapshot</entry>
13711       </row>
13712       <row>
13713        <entry><literal><function>txid_snapshot_xip(<parameter>txid_snapshot</parameter>)</function></literal></entry>
13714        <entry><type>setof bigint</type></entry>
13715        <entry>get in-progress transaction IDs in snapshot</entry>
13716       </row>
13717       <row>
13718        <entry><literal><function>txid_snapshot_xmax(<parameter>txid_snapshot</parameter>)</function></literal></entry>
13719        <entry><type>bigint</type></entry>
13720        <entry>get <literal>xmax</literal> of snapshot</entry>
13721       </row>
13722       <row>
13723        <entry><literal><function>txid_snapshot_xmin(<parameter>txid_snapshot</parameter>)</function></literal></entry>
13724        <entry><type>bigint</type></entry>
13725        <entry>get <literal>xmin</literal> of snapshot</entry>
13726       </row>
13727       <row>
13728        <entry><literal><function>txid_visible_in_snapshot(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</function></literal></entry>
13729        <entry><type>boolean</type></entry>
13730        <entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
13731       </row>
13732      </tbody>
13733     </tgroup>
13734    </table>
13735
13736    <para>
13737     The internal transaction ID type (<type>xid</>) is 32 bits wide and
13738     wraps around every 4 billion transactions.  However, these functions
13739     export a 64-bit format that is extended with an <quote>epoch</> counter
13740     so it will not wrap around during the life of an installation.
13741     The data type used by these functions, <type>txid_snapshot</type>,
13742     stores information about transaction ID
13743     visibility at a particular moment in time.  Its components are
13744     described in <xref linkend="functions-txid-snapshot-parts">.
13745    </para>
13746
13747    <table id="functions-txid-snapshot-parts">
13748     <title>Snapshot Components</title>
13749     <tgroup cols="2">
13750      <thead>
13751       <row>
13752        <entry>Name</entry>
13753        <entry>Description</entry>
13754       </row>
13755      </thead>
13756
13757      <tbody>
13758
13759       <row>
13760        <entry><type>xmin</type></entry>
13761        <entry>
13762          Earliest transaction ID (txid) that is still active.  All earlier
13763          transactions will either be committed and visible, or rolled
13764          back and dead.
13765        </entry>
13766       </row>
13767
13768       <row>
13769        <entry><type>xmax</type></entry>
13770        <entry>
13771         First as-yet-unassigned txid.  All txids greater than or equal to this
13772         are not yet started as of the time of the snapshot, and thus invisible.
13773        </entry>
13774       </row>
13775
13776       <row>
13777        <entry><type>xip_list</type></entry>
13778        <entry>
13779         Active txids at the time of the snapshot.  The list
13780         includes only those active txids between <literal>xmin</>
13781         and <literal>xmax</>; there might be active txids higher
13782         than <literal>xmax</>.  A txid that is <literal>xmin &lt;= txid &lt;
13783         xmax</literal> and not in this list was already completed
13784         at the time of the snapshot, and thus either visible or
13785         dead according to its commit status.  The list does not
13786         include txids of subtransactions.
13787        </entry>
13788       </row>
13789
13790      </tbody>
13791     </tgroup>
13792    </table>
13793
13794    <para>
13795     <type>txid_snapshot</>'s textual representation is
13796     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
13797     For example <literal>10:20:10,14,15</literal> means
13798     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
13799    </para>
13800   </sect1>
13801
13802   <sect1 id="functions-admin">
13803    <title>System Administration Functions</title>
13804
13805    <para>
13806     <xref linkend="functions-admin-set-table"> shows the functions
13807     available to query and alter run-time configuration parameters.
13808    </para>
13809
13810    <table id="functions-admin-set-table">
13811     <title>Configuration Settings Functions</title>
13812     <tgroup cols="3">
13813      <thead>
13814       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13815      </thead>
13816
13817      <tbody>
13818       <row>
13819        <entry>
13820         <indexterm>
13821          <primary>current_setting</primary>
13822         </indexterm>
13823         <literal><function>current_setting(<parameter>setting_name</parameter>)</function></literal>
13824        </entry>
13825        <entry><type>text</type></entry>
13826        <entry>get current value of setting</entry>
13827       </row>
13828       <row>
13829        <entry>
13830         <indexterm>
13831          <primary>set_config</primary>
13832         </indexterm>
13833         <literal><function>set_config(<parameter>setting_name</parameter>,
13834                              <parameter>new_value</parameter>,
13835                              <parameter>is_local</parameter>)</function></literal>
13836        </entry>
13837        <entry><type>text</type></entry>
13838        <entry>set parameter and return new value</entry>
13839       </row>
13840      </tbody>
13841     </tgroup>
13842    </table>
13843
13844    <indexterm>
13845     <primary>SET</primary>
13846    </indexterm>
13847
13848    <indexterm>
13849     <primary>SHOW</primary>
13850    </indexterm>
13851
13852    <indexterm>
13853     <primary>configuration</primary>
13854     <secondary sortas="server">of the server</secondary>
13855     <tertiary>functions</tertiary>
13856    </indexterm>
13857
13858    <para>
13859     The function <function>current_setting</function> yields the
13860     current value of the setting <parameter>setting_name</parameter>.
13861     It corresponds to the <acronym>SQL</acronym> command
13862     <command>SHOW</command>.  An example:
13863 <programlisting>
13864 SELECT current_setting('datestyle');
13865
13866  current_setting
13867 -----------------
13868  ISO, MDY
13869 (1 row)
13870 </programlisting>
13871    </para>
13872
13873    <para>
13874     <function>set_config</function> sets the parameter
13875     <parameter>setting_name</parameter> to
13876     <parameter>new_value</parameter>.  If
13877     <parameter>is_local</parameter> is <literal>true</literal>, the
13878     new value will only apply to the current transaction. If you want
13879     the new value to apply for the current session, use
13880     <literal>false</literal> instead. The function corresponds to the
13881     SQL command <command>SET</command>. An example:
13882 <programlisting>
13883 SELECT set_config('log_statement_stats', 'off', false);
13884
13885  set_config
13886 ------------
13887  off
13888 (1 row)
13889 </programlisting>
13890    </para>
13891
13892    <indexterm>
13893     <primary>pg_cancel_backend</primary>
13894    </indexterm>
13895    <indexterm>
13896     <primary>pg_reload_conf</primary>
13897    </indexterm>
13898    <indexterm>
13899     <primary>pg_rotate_logfile</primary>
13900    </indexterm>
13901    <indexterm>
13902     <primary>pg_terminate_backend</primary>
13903    </indexterm>
13904
13905    <indexterm>
13906     <primary>signal</primary>
13907     <secondary sortas="backend">backend processes</secondary>
13908    </indexterm>
13909
13910    <para>
13911     The functions shown in <xref
13912     linkend="functions-admin-signal-table"> send control signals to
13913     other server processes.  Use of these functions is restricted
13914     to superusers.
13915    </para>
13916
13917    <table id="functions-admin-signal-table">
13918     <title>Server Signalling Functions</title>
13919     <tgroup cols="3">
13920      <thead>
13921       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13922       </row>
13923      </thead>
13924
13925      <tbody>
13926       <row>
13927        <entry>
13928         <literal><function>pg_cancel_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
13929         </entry>
13930        <entry><type>boolean</type></entry>
13931        <entry>Cancel a backend's current query</entry>
13932       </row>
13933       <row>
13934        <entry>
13935         <literal><function>pg_reload_conf()</function></literal>
13936         </entry>
13937        <entry><type>boolean</type></entry>
13938        <entry>Cause server processes to reload their configuration files</entry>
13939       </row>
13940       <row>
13941        <entry>
13942         <literal><function>pg_rotate_logfile()</function></literal>
13943         </entry>
13944        <entry><type>boolean</type></entry>
13945        <entry>Rotate server's log file</entry>
13946       </row>
13947       <row>
13948        <entry>
13949         <literal><function>pg_terminate_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
13950         </entry>
13951        <entry><type>boolean</type></entry>
13952        <entry>Terminate a backend</entry>
13953       </row>
13954      </tbody>
13955     </tgroup>
13956    </table>
13957
13958    <para>
13959     Each of these functions returns <literal>true</literal> if
13960     successful and <literal>false</literal> otherwise.
13961    </para>
13962
13963    <para>
13964     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
13965     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
13966     respectively) to backend processes identified by process ID.
13967     The process ID of an active backend can be found from
13968     the <structfield>procpid</structfield> column of the
13969     <structname>pg_stat_activity</structname> view, or by listing the
13970     <command>postgres</command> processes on the server (using
13971     <application>ps</> on Unix or the <application>Task
13972     Manager</> on <productname>Windows</>).
13973    </para>
13974
13975    <para>
13976     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
13977     to the server, causing configuration files
13978     to be reloaded by all server processes.
13979    </para>
13980
13981    <para>
13982     <function>pg_rotate_logfile</> signals the log-file manager to switch
13983     to a new output file immediately.  This works only when the built-in
13984     log collector is running, since otherwise there is no log-file manager
13985     subprocess.
13986    </para>
13987
13988    <indexterm>
13989     <primary>backup</primary>
13990    </indexterm>
13991    <indexterm>
13992     <primary>pg_create_restore_point</primary>
13993    </indexterm>
13994    <indexterm>
13995     <primary>pg_current_xlog_insert_location</primary>
13996    </indexterm>
13997    <indexterm>
13998     <primary>pg_current_xlog_location</primary>
13999    </indexterm>
14000    <indexterm>
14001     <primary>pg_start_backup</primary>
14002    </indexterm>
14003    <indexterm>
14004     <primary>pg_stop_backup</primary>
14005    </indexterm>
14006    <indexterm>
14007     <primary>pg_switch_xlog</primary>
14008    </indexterm>
14009    <indexterm>
14010     <primary>pg_xlogfile_name</primary>
14011    </indexterm>
14012    <indexterm>
14013     <primary>pg_xlogfile_name_offset</primary>
14014    </indexterm>
14015
14016    <para>
14017     The functions shown in <xref
14018     linkend="functions-admin-backup-table"> assist in making on-line backups.
14019     These functions cannot be executed during recovery.
14020    </para>
14021
14022    <table id="functions-admin-backup-table">
14023     <title>Backup Control Functions</title>
14024     <tgroup cols="3">
14025      <thead>
14026       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14027       </row>
14028      </thead>
14029
14030      <tbody>
14031       <row>
14032        <entry>
14033         <literal><function>pg_create_restore_point(<parameter>name</> <type>text</>)</function></literal>
14034         </entry>
14035        <entry><type>text</type></entry>
14036        <entry>Create a named point for performing restore (restricted to superusers)</entry>
14037       </row>
14038       <row>
14039        <entry>
14040         <literal><function>pg_current_xlog_insert_location()</function></literal>
14041         </entry>
14042        <entry><type>text</type></entry>
14043        <entry>Get current transaction log insert location</entry>
14044       </row>
14045       <row>
14046        <entry>
14047         <literal><function>pg_current_xlog_location()</function></literal>
14048         </entry>
14049        <entry><type>text</type></entry>
14050        <entry>Get current transaction log write location</entry>
14051       </row>
14052       <row>
14053        <entry>
14054         <literal><function>pg_start_backup(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> </optional>)</function></literal>
14055         </entry>
14056        <entry><type>text</type></entry>
14057        <entry>Prepare for performing on-line backup (restricted to superusers or replication roles)</entry>
14058       </row>
14059       <row>
14060        <entry>
14061         <literal><function>pg_stop_backup()</function></literal>
14062         </entry>
14063        <entry><type>text</type></entry>
14064        <entry>Finish performing on-line backup (restricted to superusers or replication roles)</entry>
14065       </row>
14066       <row>
14067        <entry>
14068         <literal><function>pg_switch_xlog()</function></literal>
14069         </entry>
14070        <entry><type>text</type></entry>
14071        <entry>Force switch to a new transaction log file (restricted to superusers)</entry>
14072       </row>
14073       <row>
14074        <entry>
14075         <literal><function>pg_xlogfile_name(<parameter>location</> <type>text</>)</function></literal>
14076         </entry>
14077        <entry><type>text</type></entry>
14078        <entry>Convert transaction log location string to file name</entry>
14079       </row>
14080       <row>
14081        <entry>
14082         <literal><function>pg_xlogfile_name_offset(<parameter>location</> <type>text</>)</function></literal>
14083         </entry>
14084        <entry><type>text</>, <type>integer</></entry>
14085        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
14086       </row>
14087      </tbody>
14088     </tgroup>
14089    </table>
14090
14091    <para>
14092     <function>pg_start_backup</> accepts an
14093     arbitrary user-defined label for the backup.  (Typically this would be
14094     the name under which the backup dump file will be stored.)  The function
14095     writes a backup label file (<filename>backup_label</>) into the
14096     database cluster's data directory, performs a checkpoint,
14097     and then returns the backup's starting transaction log location as text.
14098     The user can ignore this result value, but it is
14099     provided in case it is useful.
14100 <programlisting>
14101 postgres=# select pg_start_backup('label_goes_here');
14102  pg_start_backup
14103 -----------------
14104  0/D4445B8
14105 (1 row)
14106 </programlisting>
14107     There is an optional second parameter of type <type>boolean</type>.  If <literal>true</>,
14108     it specifies executing <function>pg_start_backup</> as quickly as
14109     possible.  This forces an immediate checkpoint which will cause a
14110     spike in I/O operations, slowing any concurrently executing queries.
14111    </para>
14112
14113    <para>
14114     <function>pg_stop_backup</> removes the label file created by
14115     <function>pg_start_backup</>, and creates a backup history file in
14116     the transaction log archive area.  The history file includes the label given to
14117     <function>pg_start_backup</>, the starting and ending transaction log locations for
14118     the backup, and the starting and ending times of the backup.  The return
14119     value is the backup's ending transaction log location (which again
14120     can be ignored).  After recording the ending location, the current
14121     transaction log insertion
14122     point is automatically advanced to the next transaction log file, so that the
14123     ending transaction log file can be archived immediately to complete the backup.
14124    </para>
14125
14126    <para>
14127     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the
14128     current file to be archived (assuming you are using continuous archiving).
14129     The return value is the ending transaction log location + 1 within the just-completed transaction log file.
14130     If there has been no transaction log activity since the last transaction log switch,
14131     <function>pg_switch_xlog</> does nothing and returns the start location
14132     of the transaction log file currently in use.
14133    </para>
14134
14135    <para>
14136     <function>pg_create_restore_point</> creates a named transaction log
14137     record that can be used as recovery target, and returns the corresponding
14138     transaction log location.  The given name can then be used with
14139     <xref linkend="recovery-target-name"> to specify the point up to which
14140     recovery will proceed.  Avoid creating multiple restore points with the
14141     same name, since recovery will stop at the first one whose name matches
14142     the recovery target.
14143    </para>
14144
14145    <para>
14146     <function>pg_current_xlog_location</> displays the current transaction log write
14147     location in the same format used by the above functions.  Similarly,
14148     <function>pg_current_xlog_insert_location</> displays the current transaction log
14149     insertion point.  The insertion point is the <quote>logical</> end
14150     of the transaction log
14151     at any instant, while the write location is the end of what has actually
14152     been written out from the server's internal buffers.  The write location
14153     is the end of what can be examined from outside the server, and is usually
14154     what you want if you are interested in archiving partially-complete transaction log
14155     files.  The insertion point is made available primarily for server
14156     debugging purposes.  These are both read-only operations and do not
14157     require superuser permissions.
14158    </para>
14159
14160    <para>
14161     You can use <function>pg_xlogfile_name_offset</> to extract the
14162     corresponding transaction log file name and byte offset from the results of any of the
14163     above functions.  For example:
14164 <programlisting>
14165 postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup());
14166         file_name         | file_offset 
14167 --------------------------+-------------
14168  00000001000000000000000D |     4039624
14169 (1 row)
14170 </programlisting>
14171     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
14172     When the given transaction log location is exactly at a transaction log file boundary, both
14173     these functions return the name of the preceding transaction log file.
14174     This is usually the desired behavior for managing transaction log archiving
14175     behavior, since the preceding file is the last one that currently
14176     needs to be archived.
14177    </para>
14178
14179    <para>
14180     For details about proper usage of these functions, see
14181     <xref linkend="continuous-archiving">.
14182    </para>
14183
14184    <indexterm>
14185     <primary>pg_is_in_recovery</primary>
14186    </indexterm>
14187    <indexterm>
14188     <primary>pg_last_xlog_receive_location</primary>
14189    </indexterm>
14190    <indexterm>
14191     <primary>pg_last_xlog_replay_location</primary>
14192    </indexterm>
14193    <indexterm>
14194     <primary>pg_last_xact_replay_timestamp</primary>
14195    </indexterm>
14196
14197    <para>
14198     The functions shown in <xref
14199     linkend="functions-recovery-info-table"> provide information
14200     about the current status of the standby.
14201     These functions may be executed during both recovery and in normal running.
14202    </para>
14203
14204    <table id="functions-recovery-info-table">
14205     <title>Recovery Information Functions</title>
14206     <tgroup cols="3">
14207      <thead>
14208       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14209       </row>
14210      </thead>
14211
14212      <tbody>
14213       <row>
14214        <entry>
14215         <literal><function>pg_is_in_recovery()</function></literal>
14216         </entry>
14217        <entry><type>bool</type></entry>
14218        <entry>True if recovery is still in progress.
14219        </entry>
14220       </row>
14221       <row>
14222        <entry>
14223         <literal><function>pg_last_xlog_receive_location()</function></literal>
14224         </entry>
14225        <entry><type>text</type></entry>
14226        <entry>Get last transaction log location received and synced to disk by
14227         streaming replication. While streaming replication is in progress
14228         this will increase monotonically. If recovery has completed this will
14229         remain static at
14230         the value of the last WAL record received and synced to disk during
14231         recovery. If streaming replication is disabled, or if it has not yet
14232         started, the function returns NULL.
14233        </entry>
14234       </row>
14235       <row>
14236        <entry>
14237         <literal><function>pg_last_xlog_replay_location()</function></literal>
14238         </entry>
14239        <entry><type>text</type></entry>
14240        <entry>Get last transaction log location replayed during recovery.
14241         If recovery is still in progress this will increase monotonically.
14242         If recovery has completed then this value will remain static at
14243         the value of the last WAL record applied during that recovery.
14244         When the server has been started normally without recovery
14245         the function returns NULL.
14246        </entry>
14247       </row>
14248       <row>
14249        <entry>
14250         <literal><function>pg_last_xact_replay_timestamp()</function></literal>
14251         </entry>
14252        <entry><type>timestamp with time zone</type></entry>
14253        <entry>Get time stamp of last transaction replayed during recovery.
14254         This is the time at which the commit or abort WAL record for that
14255         transaction was generated on the primary.
14256         If no transactions have been replayed during recovery, this function
14257         returns NULL.  Otherwise, if recovery is still in progress this will
14258         increase monotonically.  If recovery has completed then this value will
14259         remain static at the value of the last transaction applied during that
14260         recovery.  When the server has been started normally without recovery
14261         the function returns NULL.
14262        </entry>
14263       </row>
14264      </tbody>
14265     </tgroup>
14266    </table>
14267
14268    <indexterm>
14269     <primary>pg_is_xlog_replay_paused</primary>
14270    </indexterm>
14271    <indexterm>
14272     <primary>pg_xlog_replay_pause</primary>
14273    </indexterm>
14274    <indexterm>
14275     <primary>pg_xlog_replay_resume</primary>
14276    </indexterm>
14277
14278    <para>
14279     The functions shown in <xref
14280     linkend="functions-recovery-control-table"> control the progress of recovery.
14281     These functions may be executed only during recovery.
14282    </para>
14283
14284    <table id="functions-recovery-control-table">
14285     <title>Recovery Control Functions</title>
14286     <tgroup cols="3">
14287      <thead>
14288       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14289       </row>
14290      </thead>
14291
14292      <tbody>
14293       <row>
14294        <entry>
14295         <literal><function>pg_is_xlog_replay_paused()</function></literal>
14296         </entry>
14297        <entry><type>bool</type></entry>
14298        <entry>True if recovery is paused.
14299        </entry>
14300       </row>
14301       <row>
14302        <entry>
14303         <literal><function>pg_xlog_replay_pause()</function></literal>
14304         </entry>
14305        <entry><type>void</type></entry>
14306        <entry>Pauses recovery immediately.
14307        </entry>
14308       </row>
14309       <row>
14310        <entry>
14311         <literal><function>pg_xlog_replay_resume()</function></literal>
14312         </entry>
14313        <entry><type>void</type></entry>
14314        <entry>Restarts recovery if it was paused.
14315        </entry>
14316       </row>
14317      </tbody>
14318     </tgroup>
14319    </table>
14320
14321    <para>
14322     While recovery is paused no further database changes are applied.
14323     If in hot standby, all new queries will see the same consistent snapshot
14324     of the database, and no further query conflicts will be generated until
14325     recovery is resumed.
14326    </para>
14327
14328    <para>
14329     If streaming replication is disabled, the paused state may continue
14330     indefinitely without problem. While streaming replication is in
14331     progress WAL records will continue to be received, which will
14332     eventually fill available disk space, depending upon the duration of
14333     the pause, the rate of WAL generation and available disk space.
14334    </para>
14335
14336    <para>
14337     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
14338     the disk space usage of database objects.
14339    </para>
14340
14341    <indexterm>
14342     <primary>pg_column_size</primary>
14343    </indexterm>
14344    <indexterm>
14345     <primary>pg_database_size</primary>
14346    </indexterm>
14347    <indexterm>
14348     <primary>pg_indexes_size</primary>
14349    </indexterm>
14350    <indexterm>
14351     <primary>pg_relation_size</primary>
14352    </indexterm>
14353    <indexterm>
14354     <primary>pg_size_pretty</primary>
14355    </indexterm>
14356    <indexterm>
14357     <primary>pg_table_size</primary>
14358    </indexterm>
14359    <indexterm>
14360     <primary>pg_tablespace_size</primary>
14361    </indexterm>
14362    <indexterm>
14363     <primary>pg_total_relation_size</primary>
14364    </indexterm>
14365
14366    <table id="functions-admin-dbsize">
14367     <title>Database Object Size Functions</title>
14368     <tgroup cols="3">
14369      <thead>
14370       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14371       </row>
14372      </thead>
14373
14374      <tbody>
14375       <row>
14376        <entry><literal><function>pg_column_size(<type>any</type>)</function></literal></entry>
14377        <entry><type>int</type></entry>
14378        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
14379       </row>
14380       <row>
14381        <entry>
14382         <literal><function>pg_database_size(<type>oid</type>)</function></literal>
14383         </entry>
14384        <entry><type>bigint</type></entry>
14385        <entry>Disk space used by the database with the specified OID</entry>
14386       </row>
14387       <row>
14388        <entry>
14389         <literal><function>pg_database_size(<type>name</type>)</function></literal>
14390         </entry>
14391        <entry><type>bigint</type></entry>
14392        <entry>Disk space used by the database with the specified name</entry>
14393       </row>
14394       <row>
14395        <entry>
14396         <literal><function>pg_indexes_size(<type>regclass</type>)</function></literal>
14397         </entry>
14398        <entry><type>bigint</type></entry>
14399        <entry>
14400         Total disk space used by indexes attached to the specified table
14401        </entry>
14402       </row>
14403       <row>
14404        <entry>
14405         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</function></literal>
14406         </entry>
14407        <entry><type>bigint</type></entry>
14408        <entry>
14409         Disk space used by the specified fork (<literal>'main'</literal>,
14410         <literal>'fsm'</literal> or <literal>'vm'</>)
14411         of the specified table or index
14412        </entry>
14413       </row>
14414       <row>
14415        <entry>
14416         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
14417         </entry>
14418        <entry><type>bigint</type></entry>
14419        <entry>
14420         Shorthand for <literal>pg_relation_size(..., 'main')</literal>
14421        </entry>
14422       </row>
14423       <row>
14424        <entry>
14425         <literal><function>pg_size_pretty(<type>bigint</type>)</function></literal>
14426         </entry>
14427        <entry><type>text</type></entry>
14428        <entry>Converts a size in bytes into a human-readable format with size units</entry>
14429       </row>
14430       <row>
14431        <entry>
14432         <literal><function>pg_table_size(<type>regclass</type>)</function></literal>
14433         </entry>
14434        <entry><type>bigint</type></entry>
14435        <entry>
14436         Disk space used by the specified table, excluding indexes
14437         (but including TOAST, free space map, and visibility map)
14438        </entry>
14439       </row>
14440       <row>
14441        <entry>
14442         <literal><function>pg_tablespace_size(<type>oid</type>)</function></literal>
14443         </entry>
14444        <entry><type>bigint</type></entry>
14445        <entry>Disk space used by the tablespace with the specified OID</entry>
14446       </row>
14447       <row>
14448        <entry>
14449         <literal><function>pg_tablespace_size(<type>name</type>)</function></literal>
14450         </entry>
14451        <entry><type>bigint</type></entry>
14452        <entry>Disk space used by the tablespace with the specified name</entry>
14453       </row>
14454       <row>
14455        <entry>
14456         <literal><function>pg_total_relation_size(<type>regclass</type>)</function></literal>
14457         </entry>
14458        <entry><type>bigint</type></entry>
14459        <entry>
14460         Total disk space used by the specified table,
14461         including all indexes and <acronym>TOAST</> data
14462        </entry>
14463       </row>
14464      </tbody>
14465     </tgroup>
14466    </table>
14467
14468    <para>
14469     <function>pg_column_size</> shows the space used to store any individual
14470     data value.
14471    </para>
14472
14473    <para>
14474     <function>pg_total_relation_size</> accepts the OID or name of a
14475     table or toast table, and returns the total on-disk space used for
14476     that table, including all associated indexes.  This function is
14477     equivalent to <function>pg_table_size</function>
14478     <literal>+</> <function>pg_indexes_size</function>.
14479    </para>
14480
14481    <para>
14482     <function>pg_table_size</> accepts the OID or name of a table and
14483     returns the disk space needed for that table, exclusive of indexes.
14484     (TOAST space, free space map, and visibility map are included.)
14485    </para>
14486
14487    <para>
14488     <function>pg_indexes_size</> accepts the OID or name of a table and
14489     returns the total disk space used by all the indexes attached to that
14490     table.
14491    </para>
14492
14493    <para>
14494     <function>pg_database_size</function> and <function>pg_tablespace_size</>
14495     accept the OID or name of a database or tablespace, and return the total
14496     disk space used therein.
14497    </para>
14498
14499    <para>
14500     <function>pg_relation_size</> accepts the OID or name of a table, index or
14501     toast table, and returns the on-disk size in bytes. Specifying
14502     <literal>'main'</literal> or leaving out the second argument returns the
14503     size of the main data fork of the relation. Specifying
14504     <literal>'fsm'</literal> returns the size of the
14505     Free Space Map (see <xref linkend="storage-fsm">) associated with the
14506     relation. Specifying <literal>'vm'</literal> returns the size of the
14507     Visibility Map (see <xref linkend="storage-vm">) associated with the
14508     relation.  Note that this function shows the size of only one fork;
14509     for most purposes it is more convenient to use the higher-level
14510     functions <function>pg_total_relation_size</> or
14511     <function>pg_table_size</>.
14512    </para>
14513
14514    <para>
14515     <function>pg_size_pretty</> can be used to format the result of one of
14516     the other functions in a human-readable way, using kB, MB, GB or TB as
14517     appropriate.
14518    </para>
14519
14520    <para>
14521     The functions above that operate on tables or indexes accept a
14522     <type>regclass</> argument, which is simply the OID of the table or index
14523     in the <structname>pg_class</> system catalog.  You do not have to look up
14524     the OID by hand, however, since the <type>regclass</> data type's input
14525     converter will do the work for you.  Just write the table name enclosed in
14526     single quotes so that it looks like a literal constant.  For compatibility
14527     with the handling of ordinary <acronym>SQL</acronym> names, the string
14528     will be converted to lower case unless it contains double quotes around
14529     the table name.
14530    </para>
14531
14532    <para>
14533     The functions shown in <xref linkend="functions-admin-dblocation"> assist
14534     in identifying the specific disk files associated with database objects.
14535    </para>
14536
14537    <indexterm>
14538     <primary>pg_relation_filenode</primary>
14539    </indexterm>
14540    <indexterm>
14541     <primary>pg_relation_filepath</primary>
14542    </indexterm>
14543
14544    <table id="functions-admin-dblocation">
14545     <title>Database Object Location Functions</title>
14546     <tgroup cols="3">
14547      <thead>
14548       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14549       </row>
14550      </thead>
14551
14552      <tbody>
14553       <row>
14554        <entry>
14555         <literal><function>pg_relation_filenode(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
14556         </entry>
14557        <entry><type>oid</type></entry>
14558        <entry>
14559         Filenode number of the specified relation
14560        </entry>
14561       </row>
14562       <row>
14563        <entry>
14564         <literal><function>pg_relation_filepath(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
14565         </entry>
14566        <entry><type>text</type></entry>
14567        <entry>
14568         File path name of the specified relation
14569        </entry>
14570       </row>
14571      </tbody>
14572     </tgroup>
14573    </table>
14574
14575    <para>
14576     <function>pg_relation_filenode</> accepts the OID or name of a table,
14577     index, sequence, or toast table, and returns the <quote>filenode</> number
14578     currently assigned to it.  The filenode is the base component of the file
14579     name(s) used for the relation (see <xref linkend="storage-file-layout">
14580     for more information).  For most tables the result is the same as
14581     <structname>pg_class</>.<structfield>relfilenode</>, but for certain
14582     system catalogs <structfield>relfilenode</> is zero and this function must
14583     be used to get the correct value.  The function returns NULL if passed
14584     a relation that does not have storage, such as a view.
14585    </para>
14586
14587    <para>
14588     <function>pg_relation_filepath</> is similar to
14589     <function>pg_relation_filenode</>, but it returns the entire file path name
14590     (relative to the database cluster's data directory <varname>PGDATA</>) of
14591     the relation.
14592    </para>
14593
14594    <para>
14595     The functions shown in <xref
14596     linkend="functions-admin-genfile"> provide native access to
14597     files on the machine hosting the server. Only files within the
14598     database cluster directory and the <varname>log_directory</> can be
14599     accessed.  Use a relative path for files in the cluster directory,
14600     and a path matching the <varname>log_directory</> configuration setting
14601     for log files.  Use of these functions is restricted to superusers.
14602    </para>
14603
14604    <table id="functions-admin-genfile">
14605     <title>Generic File Access Functions</title>
14606     <tgroup cols="3">
14607      <thead>
14608       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14609       </row>
14610      </thead>
14611
14612      <tbody>
14613       <row>
14614        <entry>
14615         <literal><function>pg_ls_dir(<parameter>dirname</> <type>text</>)</function></literal>
14616        </entry>
14617        <entry><type>setof text</type></entry>
14618        <entry>List the contents of a directory</entry>
14619       </row>
14620       <row>
14621        <entry>
14622         <literal><function>pg_read_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
14623        </entry>
14624        <entry><type>text</type></entry>
14625        <entry>Return the contents of a text file</entry>
14626       </row>
14627       <row>
14628        <entry>
14629         <literal><function>pg_read_binary_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
14630        </entry>
14631        <entry><type>bytea</type></entry>
14632        <entry>Return the contents of a file</entry>
14633       </row>
14634       <row>
14635        <entry>
14636         <literal><function>pg_stat_file(<parameter>filename</> <type>text</>)</function></literal>
14637        </entry>
14638        <entry><type>record</type></entry>
14639        <entry>Return information about a file</entry>
14640       </row>
14641      </tbody>
14642     </tgroup>
14643    </table>
14644
14645    <indexterm>
14646     <primary>pg_ls_dir</primary>
14647    </indexterm>
14648    <para>
14649     <function>pg_ls_dir</> returns all the names in the specified
14650     directory, except the special entries <quote><literal>.</></> and
14651     <quote><literal>..</></>.
14652    </para>
14653
14654    <indexterm>
14655     <primary>pg_read_file</primary>
14656    </indexterm>
14657    <para>
14658     <function>pg_read_file</> returns part of a text file, starting
14659     at the given <parameter>offset</>, returning at most <parameter>length</>
14660     bytes (less if the end of file is reached first).  If <parameter>offset</>
14661     is negative, it is relative to the end of the file.
14662     If <parameter>offset</> and <parameter>length</> are omitted, the entire
14663     file is returned.  The bytes read from the file are interpreted as a string
14664     in the server encoding; an error is thrown if they are not valid in that
14665     encoding.
14666    </para>
14667
14668    <indexterm>
14669     <primary>pg_read_binary_file</primary>
14670    </indexterm>
14671    <para>
14672     <function>pg_read_binary_file</> is similar to
14673     <function>pg_read_file</>, except that the result is a <type>bytea</type> value;
14674     accordingly, no encoding checks are performed.
14675     In combination with the <function>convert_from</> function, this function
14676     can be used to read a file in a specified encoding:
14677 <programlisting>
14678 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
14679 </programlisting>
14680    </para>
14681
14682    <indexterm>
14683     <primary>pg_stat_file</primary>
14684    </indexterm>
14685    <para>
14686     <function>pg_stat_file</> returns a record containing the file
14687     size, last accessed time stamp, last modified time stamp,
14688     last file status change time stamp (Unix platforms only),
14689     file creation time stamp (Windows only), and a <type>boolean</type>
14690     indicating if it is a directory.  Typical usages include:
14691 <programlisting>
14692 SELECT * FROM pg_stat_file('filename');
14693 SELECT (pg_stat_file('filename')).modification;
14694 </programlisting>
14695    </para>
14696
14697    <para>
14698     The functions shown in <xref linkend="functions-advisory-locks"> manage
14699     advisory locks.  For details about proper use of these functions, see
14700     <xref linkend="advisory-locks">.
14701    </para>
14702
14703    <table id="functions-advisory-locks">
14704     <title>Advisory Lock Functions</title>
14705     <tgroup cols="3">
14706      <thead>
14707       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14708       </row>
14709      </thead>
14710
14711      <tbody>
14712       <row>
14713        <entry>
14714         <literal><function>pg_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
14715        </entry>
14716        <entry><type>void</type></entry>
14717        <entry>Obtain exclusive session level advisory lock</entry>
14718       </row>
14719       <row>
14720        <entry>
14721         <literal><function>pg_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14722        </entry>
14723        <entry><type>void</type></entry>
14724        <entry>Obtain exclusive session level advisory lock</entry>
14725       </row>
14726       <row>
14727        <entry>
14728         <literal><function>pg_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14729        </entry>
14730        <entry><type>void</type></entry>
14731        <entry>Obtain shared session level advisory lock</entry>
14732       </row>
14733       <row>
14734        <entry>
14735         <literal><function>pg_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14736        </entry>
14737        <entry><type>void</type></entry>
14738        <entry>Obtain shared session level advisory lock</entry>
14739       </row>
14740       <row>
14741        <entry>
14742         <literal><function>pg_advisory_unlock(<parameter>key</> <type>bigint</>)</function></literal>
14743        </entry>
14744        <entry><type>boolean</type></entry>
14745        <entry>Release an exclusive session level advisory lock</entry>
14746       </row>
14747       <row>
14748        <entry>
14749         <literal><function>pg_advisory_unlock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14750        </entry>
14751        <entry><type>boolean</type></entry>
14752        <entry>Release an exclusive session level advisory lock</entry>
14753       </row>
14754       <row>
14755        <entry>
14756         <literal><function>pg_advisory_unlock_all()</function></literal>
14757        </entry>
14758        <entry><type>void</type></entry>
14759        <entry>Release all session level advisory locks held by the current session</entry>
14760       </row>
14761       <row>
14762        <entry>
14763         <literal><function>pg_advisory_unlock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14764        </entry>
14765        <entry><type>boolean</type></entry>
14766        <entry>Release a shared session level advisory lock</entry>
14767       </row>
14768       <row>
14769        <entry>
14770         <literal><function>pg_advisory_unlock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14771        </entry>
14772        <entry><type>boolean</type></entry>
14773        <entry>Release a shared session level advisory lock</entry>
14774       </row>
14775       <row>
14776        <entry>
14777         <literal><function>pg_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
14778        </entry>
14779        <entry><type>void</type></entry>
14780        <entry>Obtain exclusive transaction level advisory lock</entry>
14781       </row>
14782       <row>
14783        <entry>
14784         <literal><function>pg_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14785        </entry>
14786        <entry><type>void</type></entry>
14787        <entry>Obtain exclusive transaction level advisory lock</entry>
14788       </row>
14789       <row>
14790        <entry>
14791         <literal><function>pg_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14792        </entry>
14793        <entry><type>void</type></entry>
14794        <entry>Obtain shared transaction level advisory lock</entry>
14795       </row>
14796       <row>
14797        <entry>
14798         <literal><function>pg_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14799        </entry>
14800        <entry><type>void</type></entry>
14801        <entry>Obtain shared advisory lock for the current transaction</entry>
14802       </row>
14803       <row>
14804        <entry>
14805         <literal><function>pg_try_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
14806        </entry>
14807        <entry><type>boolean</type></entry>
14808        <entry>Obtain exclusive session level advisory lock if available</entry>
14809       </row>
14810       <row>
14811        <entry>
14812         <literal><function>pg_try_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14813        </entry>
14814        <entry><type>boolean</type></entry>
14815        <entry>Obtain exclusive session level advisory lock if available</entry>
14816       </row>
14817       <row>
14818        <entry>
14819         <literal><function>pg_try_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14820        </entry>
14821        <entry><type>boolean</type></entry>
14822        <entry>Obtain shared session level advisory lock if available</entry>
14823       </row>
14824       <row>
14825        <entry>
14826         <literal><function>pg_try_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14827        </entry>
14828        <entry><type>boolean</type></entry>
14829        <entry>Obtain shared session level advisory lock if available</entry>
14830       </row>
14831       <row>
14832        <entry>
14833         <literal><function>pg_try_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
14834        </entry>
14835        <entry><type>boolean</type></entry>
14836        <entry>Obtain exclusive transaction level advisory lock if available</entry>
14837       </row>
14838       <row>
14839        <entry>
14840         <literal><function>pg_try_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14841        </entry>
14842        <entry><type>boolean</type></entry>
14843        <entry>Obtain exclusive transaction level advisory lock if available</entry>
14844       </row>
14845       <row>
14846        <entry>
14847         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14848        </entry>
14849        <entry><type>boolean</type></entry>
14850        <entry>Obtain shared transaction level advisory lock if available</entry>
14851       </row>
14852       <row>
14853        <entry>
14854         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14855        </entry>
14856        <entry><type>boolean</type></entry>
14857        <entry>Obtain shared transaction level advisory lock if available</entry>
14858       </row>
14859      </tbody>
14860     </tgroup>
14861    </table>
14862
14863    <indexterm>
14864     <primary>pg_advisory_lock</primary>
14865    </indexterm>
14866    <para>
14867     <function>pg_advisory_lock</> locks an application-defined resource,
14868     which can be identified either by a single 64-bit key value or two
14869     32-bit key values (note that these two key spaces do not overlap).
14870     The key type is specified in <literal>pg_locks.objid</>.  If
14871     another session already holds a lock on the same resource, the
14872     function will wait until the resource becomes available.  The lock
14873     is exclusive.  Multiple lock requests stack, so that if the same resource
14874     is locked three times it must be also unlocked three times to be
14875     released for other sessions' use.
14876    </para>
14877
14878    <indexterm>
14879     <primary>pg_advisory_lock_shared</primary>
14880    </indexterm>
14881    <para>
14882     <function>pg_advisory_lock_shared</> works the same as
14883     <function>pg_advisory_lock</>,
14884     except the lock can be shared with other sessions requesting shared locks.
14885     Only would-be exclusive lockers are locked out.
14886    </para>
14887
14888    <indexterm>
14889     <primary>pg_try_advisory_lock</primary>
14890    </indexterm>
14891    <para>
14892     <function>pg_try_advisory_lock</> is similar to
14893     <function>pg_advisory_lock</>, except the function will not wait for the
14894     lock to become available.  It will either obtain the lock immediately and
14895     return <literal>true</>, or return <literal>false</> if the lock cannot be
14896     acquired immediately.
14897    </para>
14898
14899    <indexterm>
14900     <primary>pg_try_advisory_lock_shared</primary>
14901    </indexterm>
14902    <para>
14903     <function>pg_try_advisory_lock_shared</> works the same as
14904     <function>pg_try_advisory_lock</>, except it attempts to acquire
14905     a shared rather than an exclusive lock.
14906    </para>
14907
14908    <indexterm>
14909     <primary>pg_advisory_xact_lock</primary>
14910    </indexterm>
14911    <para>
14912     <function>pg_advisory_xact_lock</> works the same as
14913     <function>pg_advisory_lock</>, expect the lock is automatically released
14914     at the end of the current transaction and can not be released explicitly.
14915    </para>
14916
14917    <indexterm>
14918     <primary>pg_advisory_xact_lock_shared</primary>
14919    </indexterm>
14920    <para>
14921     <function>pg_advisory_xact_lock_shared</> works the same as
14922     <function>pg_advisory_lock_shared</>, expect the lock is automatically released
14923     at the end of the current transaction and can not be released explicitly.
14924    </para>
14925
14926    <indexterm>
14927     <primary>pg_try_advisory_xact_lock</primary>
14928    </indexterm>
14929    <para>
14930     <function>pg_try_advisory_xact_lock</> works the same as
14931     <function>pg_try_advisory_lock</>, expect the lock, if acquired,
14932     is automatically released at the end of the current transaction and
14933     can not be released explicitly.
14934    </para>
14935
14936    <indexterm>
14937     <primary>pg_try_advisory_xact_lock_shared</primary>
14938    </indexterm>
14939    <para>
14940     <function>pg_try_advisory_xact_lock_shared</> works the same as
14941     <function>pg_try_advisory_lock_shared</>, expect the lock, if acquired,
14942     is automatically released at the end of the current transaction and
14943     can not be released explicitly.
14944    </para>
14945
14946    <indexterm>
14947     <primary>pg_advisory_unlock</primary>
14948    </indexterm>
14949    <para>
14950     <function>pg_advisory_unlock</> will release a previously-acquired
14951     exclusive session level advisory lock.  It
14952     returns <literal>true</> if the lock is successfully released.
14953     If the lock was not held, it will return <literal>false</>,
14954     and in addition, an SQL warning will be raised by the server.
14955    </para>
14956
14957    <indexterm>
14958     <primary>pg_advisory_unlock_shared</primary>
14959    </indexterm>
14960    <para>
14961     <function>pg_advisory_unlock_shared</> works the same as
14962     <function>pg_advisory_unlock</>,
14963     except it releases a shared session level advisory lock.
14964    </para>
14965
14966    <indexterm>
14967     <primary>pg_advisory_unlock_all</primary>
14968    </indexterm>
14969    <para>
14970     <function>pg_advisory_unlock_all</> will release all session level advisory
14971     locks held by the current session.  (This function is implicitly invoked
14972     at session end, even if the client disconnects ungracefully.)
14973    </para>
14974
14975   </sect1>
14976
14977   <sect1 id="functions-trigger">
14978    <title>Trigger Functions</title>
14979
14980    <indexterm>
14981      <primary>suppress_redundant_updates_trigger</primary>
14982    </indexterm>
14983
14984    <para>
14985       Currently <productname>PostgreSQL</> provides one built in trigger
14986       function, <function>suppress_redundant_updates_trigger</>,
14987       which will prevent any update
14988       that does not actually change the data in the row from taking place, in
14989       contrast to the normal behavior which always performs the update
14990       regardless of whether or not the data has changed. (This normal behavior
14991       makes updates run faster, since no checking is required, and is also
14992       useful in certain cases.)
14993     </para>
14994
14995     <para>
14996       Ideally, you should normally avoid running updates that don't actually
14997       change the data in the record. Redundant updates can cost considerable
14998       unnecessary time, especially if there are lots of indexes to alter,
14999       and space in dead rows that will eventually have to be vacuumed.
15000       However, detecting such situations in client code is not
15001       always easy, or even possible, and writing expressions to detect
15002       them can be error-prone. An alternative is to use
15003       <function>suppress_redundant_updates_trigger</>, which will skip
15004       updates that don't change the data. You should use this with care,
15005       however. The trigger takes a small but non-trivial time for each record,
15006       so if most of the records affected by an update are actually changed,
15007       use of this trigger will actually make the update run slower.
15008     </para>
15009
15010     <para>
15011       The <function>suppress_redundant_updates_trigger</> function can be
15012       added to a table like this:
15013 <programlisting>
15014 CREATE TRIGGER z_min_update
15015 BEFORE UPDATE ON tablename
15016 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
15017 </programlisting>
15018       In most cases, you would want to fire this trigger last for each row.
15019       Bearing in mind that triggers fire in name order, you would then
15020       choose a trigger name that comes after the name of any other trigger
15021       you might have on the table.
15022     </para>
15023     <para>
15024        For more information about creating triggers, see
15025         <xref linkend="SQL-CREATETRIGGER">.
15026     </para>
15027   </sect1>
15028 </chapter>