]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
Revert addition of third argument to format_type().
[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 Boolean logic where the null value represents
86     <quote>unknown</quote>.  Observe the following truth tables:
87
88     <informaltable>
89      <tgroup cols="4">
90       <thead>
91        <row>
92         <entry><replaceable>a</replaceable></entry>
93         <entry><replaceable>b</replaceable></entry>
94         <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
95         <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
96        </row>
97       </thead>
98
99       <tbody>
100        <row>
101         <entry>TRUE</entry>
102         <entry>TRUE</entry>
103         <entry>TRUE</entry>
104         <entry>TRUE</entry>
105        </row>
106
107        <row>
108         <entry>TRUE</entry>
109         <entry>FALSE</entry>
110         <entry>FALSE</entry>
111         <entry>TRUE</entry>
112        </row>
113
114        <row>
115         <entry>TRUE</entry>
116         <entry>NULL</entry>
117         <entry>NULL</entry>
118         <entry>TRUE</entry>
119        </row>
120
121        <row>
122         <entry>FALSE</entry>
123         <entry>FALSE</entry>
124         <entry>FALSE</entry>
125         <entry>FALSE</entry>
126        </row>
127
128        <row>
129         <entry>FALSE</entry>
130         <entry>NULL</entry>
131         <entry>FALSE</entry>
132         <entry>NULL</entry>
133        </row>
134
135        <row>
136         <entry>NULL</entry>
137         <entry>NULL</entry>
138         <entry>NULL</entry>
139         <entry>NULL</entry>
140        </row>
141       </tbody>
142      </tgroup>
143     </informaltable>
144
145     <informaltable>
146      <tgroup cols="2">
147       <thead>
148        <row>
149         <entry><replaceable>a</replaceable></entry>
150         <entry>NOT <replaceable>a</replaceable></entry>
151        </row>
152       </thead>
153
154       <tbody>
155        <row>
156         <entry>TRUE</entry>
157         <entry>FALSE</entry>
158        </row>
159
160        <row>
161         <entry>FALSE</entry>
162         <entry>TRUE</entry>
163        </row>
164
165        <row>
166         <entry>NULL</entry>
167         <entry>NULL</entry>
168        </row>
169       </tbody>
170      </tgroup>
171     </informaltable>
172    </para>
173
174    <para>
175     The operators <literal>AND</literal> and <literal>OR</literal> are
176     commutative, that is, you can switch the left and right operand
177     without affecting the result.  But see <xref
178     linkend="syntax-express-eval"> for more information about the
179     order of evaluation of subexpressions.
180    </para>
181   </sect1>
182
183   <sect1 id="functions-comparison">
184    <title>Comparison Operators</title>
185
186    <indexterm zone="functions-comparison">
187     <primary>comparison</primary>
188     <secondary>operators</secondary>
189    </indexterm>
190
191    <para>
192     The usual comparison operators are available, shown in <xref
193     linkend="functions-comparison-table">.
194    </para>
195
196    <table id="functions-comparison-table">
197     <title>Comparison Operators</title>
198     <tgroup cols="2">
199      <thead>
200       <row>
201        <entry>Operator</entry>
202        <entry>Description</entry>
203       </row>
204      </thead>
205
206      <tbody>
207       <row>
208        <entry> <literal>&lt;</literal> </entry>
209        <entry>less than</entry>
210       </row>
211
212       <row>
213        <entry> <literal>&gt;</literal> </entry>
214        <entry>greater than</entry>
215       </row>
216
217       <row>
218        <entry> <literal>&lt;=</literal> </entry>
219        <entry>less than or equal to</entry>
220       </row>
221
222       <row>
223        <entry> <literal>&gt;=</literal> </entry>
224        <entry>greater than or equal to</entry>
225       </row>
226
227       <row>
228        <entry> <literal>=</literal> </entry>
229        <entry>equal</entry>
230       </row>
231
232       <row>
233        <entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
234        <entry>not equal</entry>
235       </row>
236      </tbody>
237     </tgroup>
238    </table>
239
240    <note>
241     <para>
242      The <literal>!=</literal> operator is converted to
243      <literal>&lt;&gt;</literal> in the parser stage.  It is not
244      possible to implement <literal>!=</literal> and
245      <literal>&lt;&gt;</literal> operators that do different things.
246     </para>
247    </note>
248
249    <para>
250     Comparison operators are available for all relevant data types.
251     All comparison operators are binary operators that
252     return values of type <type>boolean</type>; expressions like
253     <literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
254     no <literal>&lt;</literal> operator to compare a Boolean value with
255     <literal>3</literal>).
256    </para>
257
258    <para>
259     <indexterm>
260      <primary>BETWEEN</primary>
261     </indexterm>
262     In addition to the comparison operators, the special
263     <token>BETWEEN</token> construct is available:
264 <synopsis>
265 <replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
266 </synopsis>
267     is equivalent to
268 <synopsis>
269 <replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
270 </synopsis>
271     Notice that <token>BETWEEN</token> treats the endpoint values as included
272     in the range.
273     <literal>NOT BETWEEN</literal> does the opposite comparison:
274 <synopsis>
275 <replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
276 </synopsis>
277     is equivalent to
278 <synopsis>
279 <replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
280 </synopsis>
281     <indexterm>
282      <primary>BETWEEN SYMMETRIC</primary>
283     </indexterm>
284     <literal>BETWEEN SYMMETRIC</> is the same as <literal>BETWEEN</>
285     except there is no requirement that the argument to the left of
286     <literal>AND</> be less than or equal to the argument on the right.
287     If it is not, those two arguments are automatically swapped, so that
288     a nonempty range is always implied.
289    </para>
290
291    <para>
292     <indexterm>
293      <primary>IS NULL</primary>
294     </indexterm>
295     <indexterm>
296      <primary>IS NOT NULL</primary>
297     </indexterm>
298     <indexterm>
299      <primary>ISNULL</primary>
300     </indexterm>
301     <indexterm>
302      <primary>NOTNULL</primary>
303     </indexterm>
304     To check whether a value is or is not null, use the constructs:
305 <synopsis>
306 <replaceable>expression</replaceable> IS NULL
307 <replaceable>expression</replaceable> IS NOT NULL
308 </synopsis>
309     or the equivalent, but nonstandard, constructs:
310 <synopsis>
311 <replaceable>expression</replaceable> ISNULL
312 <replaceable>expression</replaceable> NOTNULL
313 </synopsis>
314     <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
315    </para>
316
317    <para>
318     Do <emphasis>not</emphasis> write
319     <literal><replaceable>expression</replaceable> = NULL</literal>
320     because <literal>NULL</> is not <quote>equal to</quote>
321     <literal>NULL</>.  (The null value represents an unknown value,
322     and it is not known whether two unknown values are equal.) This
323     behavior conforms to the SQL standard.
324    </para>
325
326   <tip>
327    <para>
328     Some applications might expect that
329     <literal><replaceable>expression</replaceable> = NULL</literal>
330     returns true if <replaceable>expression</replaceable> evaluates to
331     the null value.  It is highly recommended that these applications
332     be modified to comply with the SQL standard. However, if that
333     cannot be done the <xref linkend="guc-transform-null-equals">
334     configuration variable is available. If it is enabled,
335     <productname>PostgreSQL</productname> will convert <literal>x =
336     NULL</literal> clauses to <literal>x IS NULL</literal>.
337    </para>
338   </tip>
339
340   <note>
341    <para>
342     If the <replaceable>expression</replaceable> is row-valued, then
343     <literal>IS NULL</> is true when the row expression itself is null
344     or when all the row's fields are null, while
345     <literal>IS NOT NULL</> is true when the row expression itself is non-null
346     and all the row's fields are non-null.  Because of this behavior,
347     <literal>IS NULL</> and <literal>IS NOT NULL</> do not always return
348     inverse results for row-valued expressions, i.e., a row-valued
349     expression that contains both NULL and non-null values will return false
350     for both tests.
351     This definition conforms to the SQL standard, and is a change from the
352     inconsistent behavior exhibited by <productname>PostgreSQL</productname>
353     versions prior to 8.2.
354    </para>
355   </note>
356
357    <para>
358     <indexterm>
359      <primary>IS DISTINCT FROM</primary>
360     </indexterm>
361     <indexterm>
362      <primary>IS NOT DISTINCT FROM</primary>
363     </indexterm>
364     Ordinary comparison operators yield null (signifying <quote>unknown</>),
365     not true or false, when either input is null.  For example,
366     <literal>7 = NULL</> yields null.  When this behavior is not suitable,
367     use the
368     <literal>IS <optional> NOT </> DISTINCT FROM</literal> constructs:
369 <synopsis>
370 <replaceable>expression</replaceable> IS DISTINCT FROM <replaceable>expression</replaceable>
371 <replaceable>expression</replaceable> IS NOT DISTINCT FROM <replaceable>expression</replaceable>
372 </synopsis>
373     For non-null inputs, <literal>IS DISTINCT FROM</literal> is
374     the same as the <literal>&lt;&gt;</> operator.  However, if both
375     inputs are null it returns false, and if only one input is
376     null it returns true.  Similarly, <literal>IS NOT DISTINCT
377     FROM</literal> is identical to <literal>=</literal> for non-null
378     inputs, but it returns true when both inputs are null, and false when only
379     one input is null. Thus, these constructs effectively act as though null
380     were a normal data value, rather than <quote>unknown</>.
381    </para>
382
383    <para>
384     <indexterm>
385      <primary>IS TRUE</primary>
386     </indexterm>
387     <indexterm>
388      <primary>IS NOT TRUE</primary>
389     </indexterm>
390     <indexterm>
391      <primary>IS FALSE</primary>
392     </indexterm>
393     <indexterm>
394      <primary>IS NOT FALSE</primary>
395     </indexterm>
396     <indexterm>
397      <primary>IS UNKNOWN</primary>
398     </indexterm>
399     <indexterm>
400      <primary>IS NOT UNKNOWN</primary>
401     </indexterm>
402     Boolean values can also be tested using the constructs
403 <synopsis>
404 <replaceable>expression</replaceable> IS TRUE
405 <replaceable>expression</replaceable> IS NOT TRUE
406 <replaceable>expression</replaceable> IS FALSE
407 <replaceable>expression</replaceable> IS NOT FALSE
408 <replaceable>expression</replaceable> IS UNKNOWN
409 <replaceable>expression</replaceable> IS NOT UNKNOWN
410 </synopsis>
411     These will always return true or false, never a null value, even when the
412     operand is null.
413     A null input is treated as the logical value <quote>unknown</>.
414     Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
415     effectively the same as <literal>IS NULL</literal> and
416     <literal>IS NOT NULL</literal>, respectively, except that the input
417     expression must be of Boolean type.
418    </para>
419
420 <!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
421    <para>
422     <indexterm>
423      <primary>IS OF</primary>
424     </indexterm>
425     <indexterm>
426      <primary>IS NOT OF</primary>
427     </indexterm>
428     It is possible to check the data type of an expression using the
429     constructs
430 <synopsis>
431 <replaceable>expression</replaceable> IS OF (typename, ...)
432 <replaceable>expression</replaceable> IS NOT OF (typename, ...)
433 </synopsis>
434     They return a boolean value based on whether the expression's data
435     type is one of the listed data types.
436    </para>
437 -->
438
439   </sect1>
440
441   <sect1 id="functions-math">
442    <title>Mathematical Functions and Operators</title>
443
444    <para>
445     Mathematical operators are provided for many
446     <productname>PostgreSQL</productname> types. For types without
447     standard mathematical conventions
448     (e.g., date/time types) we
449     describe the actual behavior in subsequent sections.
450    </para>
451
452    <para>
453     <xref linkend="functions-math-op-table"> shows the available mathematical operators.
454    </para>
455
456    <table id="functions-math-op-table">
457     <title>Mathematical Operators</title>
458
459     <tgroup cols="4">
460      <thead>
461       <row>
462        <entry>Operator</entry>
463        <entry>Description</entry>
464        <entry>Example</entry>
465        <entry>Result</entry>
466       </row>
467      </thead>
468
469      <tbody>
470       <row>
471        <entry> <literal>+</literal> </entry>
472        <entry>addition</entry>
473        <entry><literal>2 + 3</literal></entry>
474        <entry><literal>5</literal></entry>
475       </row>
476
477       <row>
478        <entry> <literal>-</literal> </entry>
479        <entry>subtraction</entry>
480        <entry><literal>2 - 3</literal></entry>
481        <entry><literal>-1</literal></entry>
482       </row>
483
484       <row>
485        <entry> <literal>*</literal> </entry>
486        <entry>multiplication</entry>
487        <entry><literal>2 * 3</literal></entry>
488        <entry><literal>6</literal></entry>
489       </row>
490
491       <row>
492        <entry> <literal>/</literal> </entry>
493        <entry>division (integer division truncates the result)</entry>
494        <entry><literal>4 / 2</literal></entry>
495        <entry><literal>2</literal></entry>
496       </row>
497
498       <row>
499        <entry> <literal>%</literal> </entry>
500        <entry>modulo (remainder)</entry>
501        <entry><literal>5 % 4</literal></entry>
502        <entry><literal>1</literal></entry>
503       </row>
504
505       <row>
506        <entry> <literal>^</literal> </entry>
507        <entry>exponentiation</entry>
508        <entry><literal>2.0 ^ 3.0</literal></entry>
509        <entry><literal>8</literal></entry>
510       </row>
511
512       <row>
513        <entry> <literal>|/</literal> </entry>
514        <entry>square root</entry>
515        <entry><literal>|/ 25.0</literal></entry>
516        <entry><literal>5</literal></entry>
517       </row>
518
519       <row>
520        <entry> <literal>||/</literal> </entry>
521        <entry>cube root</entry>
522        <entry><literal>||/ 27.0</literal></entry>
523        <entry><literal>3</literal></entry>
524       </row>
525
526       <row>
527        <entry> <literal>!</literal> </entry>
528        <entry>factorial</entry>
529        <entry><literal>5 !</literal></entry>
530        <entry><literal>120</literal></entry>
531       </row>
532
533       <row>
534        <entry> <literal>!!</literal> </entry>
535        <entry>factorial (prefix operator)</entry>
536        <entry><literal>!! 5</literal></entry>
537        <entry><literal>120</literal></entry>
538       </row>
539
540       <row>
541        <entry> <literal>@</literal> </entry>
542        <entry>absolute value</entry>
543        <entry><literal>@ -5.0</literal></entry>
544        <entry><literal>5</literal></entry>
545       </row>
546
547       <row>
548        <entry> <literal>&amp;</literal> </entry>
549        <entry>bitwise AND</entry>
550        <entry><literal>91 &amp; 15</literal></entry>
551        <entry><literal>11</literal></entry>
552       </row>
553
554       <row>
555        <entry> <literal>|</literal> </entry>
556        <entry>bitwise OR</entry>
557        <entry><literal>32 | 3</literal></entry>
558        <entry><literal>35</literal></entry>
559       </row>
560
561       <row>
562        <entry> <literal>#</literal> </entry>
563        <entry>bitwise XOR</entry>
564        <entry><literal>17 # 5</literal></entry>
565        <entry><literal>20</literal></entry>
566       </row>
567
568       <row>
569        <entry> <literal>~</literal> </entry>
570        <entry>bitwise NOT</entry>
571        <entry><literal>~1</literal></entry>
572        <entry><literal>-2</literal></entry>
573       </row>
574
575       <row>
576        <entry> <literal>&lt;&lt;</literal> </entry>
577        <entry>bitwise shift left</entry>
578        <entry><literal>1 &lt;&lt; 4</literal></entry>
579        <entry><literal>16</literal></entry>
580       </row>
581
582       <row>
583        <entry> <literal>&gt;&gt;</literal> </entry>
584        <entry>bitwise shift right</entry>
585        <entry><literal>8 &gt;&gt; 2</literal></entry>
586        <entry><literal>2</literal></entry>
587       </row>
588
589      </tbody>
590     </tgroup>
591    </table>
592
593    <para>
594     The bitwise operators work only on integral data types, whereas
595     the others are available for all numeric data types.  The bitwise
596     operators are also available for the bit
597     string types <type>bit</type> and <type>bit varying</type>, as
598     shown in <xref linkend="functions-bit-string-op-table">.
599    </para>
600
601   <para>
602    <xref linkend="functions-math-func-table"> shows the available
603    mathematical functions.  In the table, <literal>dp</literal>
604    indicates <type>double precision</type>.  Many of these functions
605    are provided in multiple forms with different argument types.
606    Except where noted, any given form of a function returns the same
607    data type as its argument.
608    The functions working with <type>double precision</type> data are mostly
609    implemented on top of the host system's C library; accuracy and behavior in
610    boundary cases can therefore vary depending on the host system.
611   </para>
612
613    <table id="functions-math-func-table">
614     <title>Mathematical Functions</title>
615     <tgroup cols="5">
616      <thead>
617       <row>
618        <entry>Function</entry>
619        <entry>Return Type</entry>
620        <entry>Description</entry>
621        <entry>Example</entry>
622        <entry>Result</entry>
623       </row>
624      </thead>
625
626      <tbody>
627       <row>
628        <entry>
629         <indexterm>
630          <primary>abs</primary>
631         </indexterm>
632         <literal><function>abs(<replaceable>x</replaceable>)</function></literal>
633        </entry>
634        <entry>(same as input)</entry>
635        <entry>absolute value</entry>
636        <entry><literal>abs(-17.4)</literal></entry>
637        <entry><literal>17.4</literal></entry>
638       </row>
639
640       <row>
641        <entry>
642         <indexterm>
643          <primary>cbrt</primary>
644         </indexterm>
645         <literal><function>cbrt(<type>dp</type>)</function></literal>
646        </entry>
647        <entry><type>dp</type></entry>
648        <entry>cube root</entry>
649        <entry><literal>cbrt(27.0)</literal></entry>
650        <entry><literal>3</literal></entry>
651       </row>
652
653       <row>
654        <entry>
655         <indexterm>
656          <primary>ceil</primary>
657         </indexterm>
658         <literal><function>ceil(<type>dp</type> or <type>numeric</type>)</function></literal>
659        </entry>
660        <entry>(same as input)</entry>
661        <entry>smallest integer not less than argument</entry>
662        <entry><literal>ceil(-42.8)</literal></entry>
663        <entry><literal>-42</literal></entry>
664       </row>
665
666       <row>
667        <entry>
668         <indexterm>
669          <primary>ceiling</primary>
670         </indexterm>
671         <literal><function>ceiling(<type>dp</type> or <type>numeric</type>)</function></literal>
672        </entry>
673        <entry>(same as input)</entry>
674        <entry>smallest integer not less than argument (alias for <function>ceil</function>)</entry>
675        <entry><literal>ceiling(-95.3)</literal></entry>
676        <entry><literal>-95</literal></entry>
677       </row>
678
679       <row>
680        <entry>
681         <indexterm>
682          <primary>degrees</primary>
683         </indexterm>
684         <literal><function>degrees(<type>dp</type>)</function></literal>
685        </entry>
686        <entry><type>dp</type></entry>
687        <entry>radians to degrees</entry>
688        <entry><literal>degrees(0.5)</literal></entry>
689        <entry><literal>28.6478897565412</literal></entry>
690       </row>
691
692       <row>
693        <entry>
694         <indexterm>
695          <primary>div</primary>
696         </indexterm>
697         <literal><function>div(<parameter>y</parameter> <type>numeric</>,
698          <parameter>x</parameter> <type>numeric</>)</function></literal>
699        </entry>
700        <entry><type>numeric</></entry>
701        <entry>integer quotient of <parameter>y</parameter>/<parameter>x</parameter></entry>
702        <entry><literal>div(9,4)</literal></entry>
703        <entry><literal>2</literal></entry>
704       </row>
705
706       <row>
707        <entry>
708         <indexterm>
709          <primary>exp</primary>
710         </indexterm>
711         <literal><function>exp(<type>dp</type> or <type>numeric</type>)</function></literal>
712        </entry>
713        <entry>(same as input)</entry>
714        <entry>exponential</entry>
715        <entry><literal>exp(1.0)</literal></entry>
716        <entry><literal>2.71828182845905</literal></entry>
717       </row>
718
719       <row>
720        <entry>
721         <indexterm>
722          <primary>floor</primary>
723         </indexterm>
724         <literal><function>floor(<type>dp</type> or <type>numeric</type>)</function></literal>
725        </entry>
726        <entry>(same as input)</entry>
727        <entry>largest integer not greater than argument</entry>
728        <entry><literal>floor(-42.8)</literal></entry>
729        <entry><literal>-43</literal></entry>
730       </row>
731
732       <row>
733        <entry>
734         <indexterm>
735          <primary>ln</primary>
736         </indexterm>
737         <literal><function>ln(<type>dp</type> or <type>numeric</type>)</function></literal>
738        </entry>
739        <entry>(same as input)</entry>
740        <entry>natural logarithm</entry>
741        <entry><literal>ln(2.0)</literal></entry>
742        <entry><literal>0.693147180559945</literal></entry>
743       </row>
744
745       <row>
746        <entry>
747         <indexterm>
748          <primary>log</primary>
749         </indexterm>
750         <literal><function>log(<type>dp</type> or <type>numeric</type>)</function></literal>
751        </entry>
752        <entry>(same as input)</entry>
753        <entry>base 10 logarithm</entry>
754        <entry><literal>log(100.0)</literal></entry>
755        <entry><literal>2</literal></entry>
756       </row>
757
758       <row>
759        <entry><literal><function>log(<parameter>b</parameter> <type>numeric</type>,
760         <parameter>x</parameter> <type>numeric</type>)</function></literal></entry>
761        <entry><type>numeric</type></entry>
762        <entry>logarithm to base <parameter>b</parameter></entry>
763        <entry><literal>log(2.0, 64.0)</literal></entry>
764        <entry><literal>6.0000000000</literal></entry>
765       </row>
766
767       <row>
768        <entry>
769         <indexterm>
770          <primary>mod</primary>
771         </indexterm>
772         <literal><function>mod(<parameter>y</parameter>,
773          <parameter>x</parameter>)</function></literal>
774        </entry>
775        <entry>(same as argument types)</entry>
776        <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
777        <entry><literal>mod(9,4)</literal></entry>
778        <entry><literal>1</literal></entry>
779       </row>
780
781       <row>
782        <entry>
783         <indexterm>
784          <primary>pi</primary>
785         </indexterm>
786         <literal><function>pi()</function></literal>
787        </entry>
788        <entry><type>dp</type></entry>
789        <entry><quote>&pi;</quote> constant</entry>
790        <entry><literal>pi()</literal></entry>
791        <entry><literal>3.14159265358979</literal></entry>
792       </row>
793
794       <row>
795        <entry>
796         <indexterm>
797          <primary>power</primary>
798         </indexterm>
799         <literal><function>power(<parameter>a</parameter> <type>dp</type>,
800         <parameter>b</parameter> <type>dp</type>)</function></literal>
801        </entry>
802        <entry><type>dp</type></entry>
803        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
804        <entry><literal>power(9.0, 3.0)</literal></entry>
805        <entry><literal>729</literal></entry>
806       </row>
807
808       <row>
809        <entry><literal><function>power(<parameter>a</parameter> <type>numeric</type>,
810         <parameter>b</parameter> <type>numeric</type>)</function></literal></entry>
811        <entry><type>numeric</type></entry>
812        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
813        <entry><literal>power(9.0, 3.0)</literal></entry>
814        <entry><literal>729</literal></entry>
815       </row>
816
817       <row>
818        <entry>
819         <indexterm>
820          <primary>radians</primary>
821         </indexterm>
822         <literal><function>radians(<type>dp</type>)</function></literal>
823        </entry>
824        <entry><type>dp</type></entry>
825        <entry>degrees to radians</entry>
826        <entry><literal>radians(45.0)</literal></entry>
827        <entry><literal>0.785398163397448</literal></entry>
828       </row>
829
830       <row>
831        <entry>
832         <indexterm>
833          <primary>random</primary>
834         </indexterm>
835         <literal><function>random()</function></literal>
836        </entry>
837        <entry><type>dp</type></entry>
838        <entry>random value in the range 0.0 &lt;= x &lt; 1.0</entry>
839        <entry><literal>random()</literal></entry>
840        <entry></entry>
841       </row>
842
843       <row>
844        <entry>
845         <indexterm>
846          <primary>round</primary>
847         </indexterm>
848         <literal><function>round(<type>dp</type> or <type>numeric</type>)</function></literal>
849        </entry>
850        <entry>(same as input)</entry>
851        <entry>round to nearest integer</entry>
852        <entry><literal>round(42.4)</literal></entry>
853        <entry><literal>42</literal></entry>
854       </row>
855
856       <row>
857        <entry><literal><function>round(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
858        <entry><type>numeric</type></entry>
859        <entry>round to <parameter>s</parameter> decimal places</entry>
860        <entry><literal>round(42.4382, 2)</literal></entry>
861        <entry><literal>42.44</literal></entry>
862       </row>
863
864       <row>
865        <entry>
866         <indexterm>
867          <primary>setseed</primary>
868         </indexterm>
869         <literal><function>setseed(<type>dp</type>)</function></literal>
870        </entry>
871        <entry><type>void</type></entry>
872        <entry>set seed for subsequent <literal>random()</literal> calls (value between -1.0 and
873        1.0, inclusive)</entry>
874        <entry><literal>setseed(0.54823)</literal></entry>
875        <entry></entry>
876       </row>
877
878       <row>
879        <entry>
880         <indexterm>
881          <primary>sign</primary>
882         </indexterm>
883         <literal><function>sign(<type>dp</type> or <type>numeric</type>)</function></literal>
884        </entry>
885        <entry>(same as input)</entry>
886        <entry>sign of the argument (-1, 0, +1)</entry>
887        <entry><literal>sign(-8.4)</literal></entry>
888        <entry><literal>-1</literal></entry>
889       </row>
890
891       <row>
892        <entry>
893         <indexterm>
894          <primary>sqrt</primary>
895         </indexterm>
896         <literal><function>sqrt(<type>dp</type> or <type>numeric</type>)</function></literal>
897        </entry>
898        <entry>(same as input)</entry>
899        <entry>square root</entry>
900        <entry><literal>sqrt(2.0)</literal></entry>
901        <entry><literal>1.4142135623731</literal></entry>
902       </row>
903
904       <row>
905        <entry>
906         <indexterm>
907          <primary>trunc</primary>
908         </indexterm>
909         <literal><function>trunc(<type>dp</type> or <type>numeric</type>)</function></literal>
910        </entry>
911        <entry>(same as input)</entry>
912        <entry>truncate toward zero</entry>
913        <entry><literal>trunc(42.8)</literal></entry>
914        <entry><literal>42</literal></entry>
915       </row>
916
917       <row>
918        <entry><literal><function>trunc(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
919        <entry><type>numeric</type></entry>
920        <entry>truncate to <parameter>s</parameter> decimal places</entry>
921        <entry><literal>trunc(42.4382, 2)</literal></entry>
922        <entry><literal>42.43</literal></entry>
923       </row>
924
925       <row>
926        <entry>
927         <indexterm>
928          <primary>width_bucket</primary>
929         </indexterm>
930         <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>
931        </entry>
932        <entry><type>int</type></entry>
933        <entry>return the bucket to which <parameter>operand</> would
934        be assigned in an equidepth histogram with <parameter>count</>
935        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
936        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
937        <entry><literal>3</literal></entry>
938       </row>
939
940       <row>
941        <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>
942        <entry><type>int</type></entry>
943        <entry>return the bucket to which <parameter>operand</> would
944        be assigned in an equidepth histogram with <parameter>count</>
945        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
946        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
947        <entry><literal>3</literal></entry>
948       </row>
949      </tbody>
950     </tgroup>
951    </table>
952
953   <para>
954    Finally, <xref linkend="functions-math-trig-table"> shows the
955    available trigonometric functions.  All trigonometric functions
956    take arguments and return values of type <type>double
957    precision</type>. Trigonometric functions arguments are expressed
958    in radians. Inverse functions return values are expressed in
959    radians.  See unit transformation functions
960    <literal><function>radians()</function></literal> and
961    <literal><function>degrees()</function></literal> above.
962   </para>
963
964    <table id="functions-math-trig-table">
965     <title>Trigonometric Functions</title>
966
967     <tgroup cols="2">
968      <thead>
969       <row>
970        <entry>Function</entry>
971        <entry>Description</entry>
972       </row>
973      </thead>
974
975      <tbody>
976       <row>
977        <entry>
978         <indexterm>
979          <primary>acos</primary>
980         </indexterm><literal><function>acos(<replaceable>x</replaceable>)</function></literal>
981        </entry>
982        <entry>inverse cosine</entry>
983       </row>
984
985       <row>
986        <entry>
987         <indexterm>
988          <primary>asin</primary>
989         </indexterm>
990         <literal><function>asin(<replaceable>x</replaceable>)</function></literal>
991        </entry>
992        <entry>inverse sine</entry>
993       </row>
994
995       <row>
996        <entry>
997         <indexterm>
998          <primary>atan</primary>
999         </indexterm>
1000         <literal><function>atan(<replaceable>x</replaceable>)</function></literal>
1001        </entry>
1002        <entry>inverse tangent</entry>
1003       </row>
1004
1005       <row>
1006        <entry>
1007         <indexterm>
1008          <primary>atan2</primary>
1009         </indexterm>
1010         <literal><function>atan2(<replaceable>y</replaceable>,
1011         <replaceable>x</replaceable>)</function></literal>
1012        </entry>
1013        <entry>inverse tangent of
1014         <literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
1015       </row>
1016
1017       <row>
1018        <entry>
1019         <indexterm>
1020          <primary>cos</primary>
1021         </indexterm>
1022         <literal><function>cos(<replaceable>x</replaceable>)</function></literal>
1023        </entry>
1024        <entry>cosine</entry>
1025       </row>
1026
1027       <row>
1028        <entry>
1029         <indexterm>
1030          <primary>cot</primary>
1031         </indexterm>
1032         <literal><function>cot(<replaceable>x</replaceable>)</function></literal>
1033        </entry>
1034        <entry>cotangent</entry>
1035       </row>
1036
1037       <row>
1038        <entry>
1039         <indexterm>
1040          <primary>sin</primary>
1041         </indexterm>
1042         <literal><function>sin(<replaceable>x</replaceable>)</function></literal>
1043        </entry>
1044        <entry>sine</entry>
1045       </row>
1046
1047       <row>
1048        <entry>
1049         <indexterm>
1050          <primary>tan</primary>
1051         </indexterm>
1052         <literal><function>tan(<replaceable>x</replaceable>)</function></literal>
1053        </entry>
1054        <entry>tangent</entry>
1055       </row>
1056      </tbody>
1057     </tgroup>
1058    </table>
1059
1060   </sect1>
1061
1062
1063   <sect1 id="functions-string">
1064    <title>String Functions and Operators</title>
1065
1066    <para>
1067     This section describes functions and operators for examining and
1068     manipulating string values.  Strings in this context include values
1069     of the types <type>character</type>, <type>character varying</type>,
1070     and <type>text</type>.  Unless otherwise noted, all
1071     of the functions listed below work on all of these types, but be
1072     wary of potential effects of automatic space-padding when using the
1073     <type>character</type> type.  Some functions also exist
1074     natively for the bit-string types.
1075    </para>
1076
1077    <para>
1078     <acronym>SQL</acronym> defines some string functions that use
1079     key words, rather than commas, to separate
1080     arguments.  Details are in
1081     <xref linkend="functions-string-sql">.
1082     <productname>PostgreSQL</> also provides versions of these functions
1083     that use the regular function invocation syntax
1084     (see <xref linkend="functions-string-other">).
1085    </para>
1086
1087    <note>
1088     <para>
1089      Before <productname>PostgreSQL</productname> 8.3, these functions would
1090      silently accept values of several non-string data types as well, due to
1091      the presence of implicit coercions from those data types to
1092      <type>text</>.  Those coercions have been removed because they frequently
1093      caused surprising behaviors.  However, the string concatenation operator
1094      (<literal>||</>) still accepts non-string input, so long as at least one
1095      input is of a string type, as shown in <xref
1096      linkend="functions-string-sql">.  For other cases, insert an explicit
1097      coercion to <type>text</> if you need to duplicate the previous behavior.
1098     </para>
1099    </note>
1100
1101    <table id="functions-string-sql">
1102     <title><acronym>SQL</acronym> String Functions and Operators</title>
1103     <tgroup cols="5">
1104      <thead>
1105       <row>
1106        <entry>Function</entry>
1107        <entry>Return Type</entry>
1108        <entry>Description</entry>
1109        <entry>Example</entry>
1110        <entry>Result</entry>
1111       </row>
1112      </thead>
1113
1114      <tbody>
1115       <row>
1116        <entry><literal><parameter>string</parameter> <literal>||</literal>
1117         <parameter>string</parameter></literal></entry>
1118        <entry> <type>text</type> </entry>
1119        <entry>
1120         String concatenation
1121         <indexterm>
1122          <primary>character string</primary>
1123          <secondary>concatenation</secondary>
1124         </indexterm>
1125        </entry>
1126        <entry><literal>'Post' || 'greSQL'</literal></entry>
1127        <entry><literal>PostgreSQL</literal></entry>
1128       </row>
1129
1130       <row>
1131        <entry>
1132         <literal><parameter>string</parameter> <literal>||</literal>
1133         <parameter>non-string</parameter></literal>
1134         or
1135         <literal><parameter>non-string</parameter> <literal>||</literal>
1136         <parameter>string</parameter></literal>
1137        </entry>
1138        <entry> <type>text</type> </entry>
1139        <entry>
1140         String concatenation with one non-string input
1141        </entry>
1142        <entry><literal>'Value: ' || 42</literal></entry>
1143        <entry><literal>Value: 42</literal></entry>
1144       </row>
1145
1146       <row>
1147        <entry>
1148         <indexterm>
1149          <primary>bit_length</primary>
1150         </indexterm>
1151         <literal><function>bit_length(<parameter>string</parameter>)</function></literal>
1152        </entry>
1153        <entry><type>int</type></entry>
1154        <entry>Number of bits in string</entry>
1155        <entry><literal>bit_length('jose')</literal></entry>
1156        <entry><literal>32</literal></entry>
1157       </row>
1158
1159       <row>
1160        <entry>
1161         <indexterm>
1162          <primary>char_length</primary>
1163         </indexterm>
1164         <literal><function>char_length(<parameter>string</parameter>)</function></literal> or <literal><function>character_length(<parameter>string</parameter>)</function></literal>
1165        </entry>
1166        <entry><type>int</type></entry>
1167        <entry>
1168         Number of characters in string
1169         <indexterm>
1170          <primary>character string</primary>
1171          <secondary>length</secondary>
1172         </indexterm>
1173         <indexterm>
1174          <primary>length</primary>
1175          <secondary sortas="character string">of a character string</secondary>
1176          <see>character string, length</see>
1177         </indexterm>
1178        </entry>
1179        <entry><literal>char_length('jose')</literal></entry>
1180        <entry><literal>4</literal></entry>
1181       </row>
1182
1183       <row>
1184        <entry>
1185         <indexterm>
1186          <primary>lower</primary>
1187         </indexterm>
1188         <literal><function>lower(<parameter>string</parameter>)</function></literal>
1189        </entry>
1190        <entry><type>text</type></entry>
1191        <entry>Convert string to lower case</entry>
1192        <entry><literal>lower('TOM')</literal></entry>
1193        <entry><literal>tom</literal></entry>
1194       </row>
1195
1196       <row>
1197        <entry>
1198         <indexterm>
1199          <primary>octet_length</primary>
1200         </indexterm>
1201         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
1202        </entry>
1203        <entry><type>int</type></entry>
1204        <entry>Number of bytes in string</entry>
1205        <entry><literal>octet_length('jose')</literal></entry>
1206        <entry><literal>4</literal></entry>
1207       </row>
1208
1209       <row>
1210        <entry>
1211         <indexterm>
1212          <primary>overlay</primary>
1213         </indexterm>
1214         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
1215        </entry>
1216        <entry><type>text</type></entry>
1217        <entry>
1218         Replace substring
1219        </entry>
1220        <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
1221        <entry><literal>Thomas</literal></entry>
1222       </row>
1223
1224       <row>
1225        <entry>
1226         <indexterm>
1227          <primary>position</primary>
1228         </indexterm>
1229         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
1230        </entry>
1231        <entry><type>int</type></entry>
1232        <entry>Location of specified substring</entry>
1233        <entry><literal>position('om' in 'Thomas')</literal></entry>
1234        <entry><literal>3</literal></entry>
1235       </row>
1236
1237       <row>
1238        <entry>
1239         <indexterm>
1240          <primary>substring</primary>
1241         </indexterm>
1242         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
1243        </entry>
1244        <entry><type>text</type></entry>
1245        <entry>
1246         Extract substring
1247        </entry>
1248        <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
1249        <entry><literal>hom</literal></entry>
1250       </row>
1251
1252       <row>
1253        <entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</function></literal></entry>
1254        <entry><type>text</type></entry>
1255        <entry>
1256         Extract substring matching POSIX regular expression. See
1257         <xref linkend="functions-matching"> for more information on pattern
1258         matching.
1259        </entry>
1260        <entry><literal>substring('Thomas' from '...$')</literal></entry>
1261        <entry><literal>mas</literal></entry>
1262       </row>
1263
1264       <row>
1265        <entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</function></literal></entry>
1266        <entry><type>text</type></entry>
1267        <entry>
1268         Extract substring matching <acronym>SQL</acronym> regular expression.
1269         See <xref linkend="functions-matching"> for more information on
1270         pattern matching.
1271        </entry>
1272        <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
1273        <entry><literal>oma</literal></entry>
1274       </row>
1275
1276       <row>
1277        <entry>
1278         <indexterm>
1279          <primary>trim</primary>
1280         </indexterm>
1281         <literal><function>trim(<optional>leading | trailing | both</optional>
1282         <optional><parameter>characters</parameter></optional> from
1283         <parameter>string</parameter>)</function></literal>
1284        </entry>
1285        <entry><type>text</type></entry>
1286        <entry>
1287         Remove the longest string containing only the
1288         <parameter>characters</parameter> (a space by default) from the
1289         start/end/both ends of the <parameter>string</parameter>
1290        </entry>
1291        <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
1292        <entry><literal>Tom</literal></entry>
1293       </row>
1294
1295       <row>
1296        <entry>
1297         <indexterm>
1298          <primary>upper</primary>
1299         </indexterm>
1300         <literal><function>upper(<parameter>string</parameter>)</function></literal>
1301        </entry>
1302        <entry><type>text</type></entry>
1303        <entry>Convert string to upper case</entry>
1304        <entry><literal>upper('tom')</literal></entry>
1305        <entry><literal>TOM</literal></entry>
1306       </row>
1307      </tbody>
1308     </tgroup>
1309    </table>
1310
1311    <para>
1312     Additional string manipulation functions are available and are
1313     listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
1314     <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
1315    </para>
1316
1317    <table id="functions-string-other">
1318     <title>Other String Functions</title>
1319     <tgroup cols="5">
1320      <thead>
1321       <row>
1322        <entry>Function</entry>
1323        <entry>Return Type</entry>
1324        <entry>Description</entry>
1325        <entry>Example</entry>
1326        <entry>Result</entry>
1327       </row>
1328      </thead>
1329
1330      <tbody>
1331       <row>
1332        <entry>
1333         <indexterm>
1334          <primary>ascii</primary>
1335         </indexterm>
1336         <literal><function>ascii(<parameter>string</parameter>)</function></literal>
1337        </entry>
1338        <entry><type>int</type></entry>
1339        <entry>
1340         <acronym>ASCII</acronym> code of the first character of the
1341         argument.  For <acronym>UTF8</acronym> returns the Unicode code
1342         point of the character.  For other multibyte encodings, the
1343         argument must be an <acronym>ASCII</acronym> character.
1344        </entry>
1345        <entry><literal>ascii('x')</literal></entry>
1346        <entry><literal>120</literal></entry>
1347       </row>
1348
1349       <row>
1350        <entry>
1351         <indexterm>
1352          <primary>btrim</primary>
1353         </indexterm>
1354         <literal><function>btrim(<parameter>string</parameter> <type>text</type>
1355         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1356        </entry>
1357        <entry><type>text</type></entry>
1358        <entry>
1359         Remove the longest string consisting only of characters
1360         in <parameter>characters</parameter> (a space by default)
1361         from the start and end of <parameter>string</parameter>
1362        </entry>
1363        <entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
1364        <entry><literal>trim</literal></entry>
1365       </row>
1366
1367       <row>
1368        <entry>
1369         <indexterm>
1370          <primary>chr</primary>
1371         </indexterm>
1372         <literal><function>chr(<type>int</type>)</function></literal>
1373        </entry>
1374        <entry><type>text</type></entry>
1375        <entry>
1376         Character with the given code. For <acronym>UTF8</acronym> the
1377         argument is treated as a Unicode code point. For other multibyte
1378         encodings the argument must designate an
1379         <acronym>ASCII</acronym> character.  The NULL (0) character is not
1380         allowed because text data types cannot store such bytes.
1381        </entry>
1382        <entry><literal>chr(65)</literal></entry>
1383        <entry><literal>A</literal></entry>
1384       </row>
1385
1386       <row>
1387        <entry>
1388         <indexterm>
1389          <primary>concat</primary>
1390         </indexterm>
1391         <literal><function>concat(<parameter>str</parameter> <type>"any"</type>
1392          [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
1393        </entry>
1394        <entry><type>text</type></entry>
1395        <entry>
1396         Concatenate all arguments. NULL arguments are ignored.
1397        </entry>
1398        <entry><literal>concat('abcde', 2, NULL, 22)</literal></entry>
1399        <entry><literal>abcde222</literal></entry>
1400       </row>
1401
1402       <row>
1403        <entry>
1404         <indexterm>
1405          <primary>concat_ws</primary>
1406         </indexterm>
1407         <literal><function>concat_ws(<parameter>sep</parameter> <type>text</type>,
1408         <parameter>str</parameter> <type>"any"</type>
1409         [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
1410        </entry>
1411        <entry><type>text</type></entry>
1412        <entry>
1413         Concatenate all but first arguments with separators. The first
1414         parameter is used as a separator. NULL arguments are ignored.
1415        </entry>
1416        <entry><literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal></entry>
1417        <entry><literal>abcde,2,22</literal></entry>
1418       </row>
1419
1420       <row>
1421        <entry>
1422         <indexterm>
1423          <primary>convert</primary>
1424         </indexterm>
1425         <literal><function>convert(<parameter>string</parameter> <type>bytea</type>,
1426         <parameter>src_encoding</parameter> <type>name</type>,
1427         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1428        </entry>
1429        <entry><type>bytea</type></entry>
1430        <entry>
1431         Convert string to <parameter>dest_encoding</parameter>.  The
1432         original encoding is specified by
1433         <parameter>src_encoding</parameter>. The
1434         <parameter>string</parameter> must be valid in this encoding.
1435         Conversions can be defined by <command>CREATE CONVERSION</command>.
1436         Also there are some predefined conversions. See <xref
1437         linkend="conversion-names"> for available conversions.
1438        </entry>
1439        <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1440        <entry><literal>text_in_utf8</literal> represented in Latin-1
1441        encoding (ISO 8859-1)</entry>
1442       </row>
1443
1444       <row>
1445        <entry>
1446         <indexterm>
1447          <primary>convert_from</primary>
1448         </indexterm>
1449         <literal><function>convert_from(<parameter>string</parameter> <type>bytea</type>,
1450         <parameter>src_encoding</parameter> <type>name</type>)</function></literal>
1451        </entry>
1452        <entry><type>text</type></entry>
1453        <entry>
1454         Convert string to the database encoding.  The original encoding
1455         is specified by <parameter>src_encoding</parameter>. The
1456         <parameter>string</parameter> must be valid in this encoding.
1457        </entry>
1458        <entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
1459        <entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
1460       </row>
1461
1462       <row>
1463        <entry>
1464         <indexterm>
1465          <primary>convert_to</primary>
1466         </indexterm>
1467         <literal><function>convert_to(<parameter>string</parameter> <type>text</type>,
1468         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1469        </entry>
1470        <entry><type>bytea</type></entry>
1471        <entry>
1472         Convert string to <parameter>dest_encoding</parameter>.
1473        </entry>
1474        <entry><literal>convert_to('some text', 'UTF8')</literal></entry>
1475        <entry><literal>some text</literal> represented in the UTF8 encoding</entry>
1476       </row>
1477
1478       <row>
1479        <entry>
1480         <indexterm>
1481          <primary>decode</primary>
1482         </indexterm>
1483         <literal><function>decode(<parameter>string</parameter> <type>text</type>,
1484         <parameter>type</parameter> <type>text</type>)</function></literal>
1485        </entry>
1486        <entry><type>bytea</type></entry>
1487        <entry>
1488         Decode binary data from <parameter>string</parameter> previously
1489         encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
1490        </entry>
1491        <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
1492        <entry><literal>123\000\001</literal></entry>
1493       </row>
1494
1495       <row>
1496        <entry>
1497         <indexterm>
1498          <primary>encode</primary>
1499         </indexterm>
1500         <literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
1501         <parameter>type</parameter> <type>text</type>)</function></literal>
1502        </entry>
1503        <entry><type>text</type></entry>
1504        <entry>
1505         Encode binary data to different representation.  Supported
1506         types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
1507         <literal>Escape</> merely outputs null bytes as <literal>\000</> and
1508         doubles backslashes.
1509        </entry>
1510        <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1511        <entry><literal>MTIzAAE=</literal></entry>
1512       </row>
1513
1514       <row>
1515        <entry>
1516         <indexterm>
1517          <primary>format</primary>
1518         </indexterm>
1519         <literal><function>format</function>(<parameter>formatstr</parameter> <type>text</type>
1520         [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</literal>
1521        </entry>
1522        <entry><type>text</type></entry>
1523        <entry>
1524          Format a string.  This function is similar to the C function
1525          <function>sprintf</>; but only the following conversions
1526          are recognized: <literal>%s</literal> interpolates the corresponding
1527          argument as a string; <literal>%I</literal> escapes its argument as
1528          an SQL identifier; <literal>%L</literal> escapes its argument as an
1529          SQL literal; <literal>%%</literal> outputs a literal <literal>%</>.
1530          A conversion can reference an explicit parameter position by preceding
1531          the conversion specifier with <literal><replaceable>n</>$</>, where
1532          <replaceable>n</replaceable> is the argument position.
1533          See also <xref linkend="plpgsql-quote-literal-example">.
1534        </entry>
1535        <entry><literal>format('Hello %s, %1$s', 'World')</literal></entry>
1536        <entry><literal>Hello World, World</literal></entry>
1537       </row>
1538
1539       <row>
1540        <entry>
1541         <indexterm>
1542          <primary>initcap</primary>
1543         </indexterm>
1544         <literal><function>initcap(<parameter>string</parameter>)</function></literal>
1545        </entry>
1546        <entry><type>text</type></entry>
1547        <entry>
1548         Convert the first letter of each word to upper case and the
1549         rest to lower case. Words are sequences of alphanumeric
1550         characters separated by non-alphanumeric characters.
1551        </entry>
1552        <entry><literal>initcap('hi THOMAS')</literal></entry>
1553        <entry><literal>Hi Thomas</literal></entry>
1554       </row>
1555
1556       <row>
1557        <entry>
1558         <indexterm>
1559          <primary>left</primary>
1560         </indexterm>
1561         <literal><function>left(<parameter>str</parameter> <type>text</type>,
1562         <parameter>n</parameter> <type>int</type>)</function></literal>
1563        </entry>
1564        <entry><type>text</type></entry>
1565        <entry>
1566         Return first <replaceable>n</> characters in the string. When <replaceable>n</>
1567         is negative, return all but last |<replaceable>n</>| characters.
1568         </entry>
1569        <entry><literal>left('abcde', 2)</literal></entry>
1570        <entry><literal>ab</literal></entry>
1571       </row>
1572
1573       <row>
1574        <entry>
1575         <indexterm>
1576          <primary>length</primary>
1577         </indexterm>
1578         <literal><function>length(<parameter>string</parameter>)</function></literal>
1579        </entry>
1580        <entry><type>int</type></entry>
1581        <entry>
1582         Number of characters in <parameter>string</parameter>
1583        </entry>
1584        <entry><literal>length('jose')</literal></entry>
1585        <entry><literal>4</literal></entry>
1586       </row>
1587
1588       <row>
1589        <entry><literal><function>length(<parameter>string</parameter><type>bytea</type>,
1590         <parameter>encoding</parameter> <type>name</type> )</function></literal></entry>
1591        <entry><type>int</type></entry>
1592        <entry>
1593         Number of characters in <parameter>string</parameter> in the given
1594         <parameter>encoding</parameter>. The <parameter>string</parameter>
1595         must be valid in this encoding.
1596        </entry>
1597        <entry><literal>length('jose', 'UTF8')</literal></entry>
1598        <entry><literal>4</literal></entry>
1599       </row>
1600
1601       <row>
1602        <entry>
1603         <indexterm>
1604          <primary>lpad</primary>
1605         </indexterm>
1606         <literal><function>lpad(<parameter>string</parameter> <type>text</type>,
1607         <parameter>length</parameter> <type>int</type>
1608         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1609        </entry>
1610        <entry><type>text</type></entry>
1611        <entry>
1612         Fill up the <parameter>string</parameter> to length
1613         <parameter>length</parameter> by prepending the characters
1614         <parameter>fill</parameter> (a space by default).  If the
1615         <parameter>string</parameter> is already longer than
1616         <parameter>length</parameter> then it is truncated (on the
1617         right).
1618        </entry>
1619        <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1620        <entry><literal>xyxhi</literal></entry>
1621       </row>
1622
1623       <row>
1624        <entry>
1625         <indexterm>
1626          <primary>ltrim</primary>
1627         </indexterm>
1628         <literal><function>ltrim(<parameter>string</parameter> <type>text</type>
1629         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1630        </entry>
1631        <entry><type>text</type></entry>
1632        <entry>
1633         Remove the longest string containing only characters from
1634         <parameter>characters</parameter> (a space by default) from the start of
1635         <parameter>string</parameter>
1636        </entry>
1637        <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
1638        <entry><literal>trim</literal></entry>
1639       </row>
1640
1641       <row>
1642        <entry>
1643         <indexterm>
1644          <primary>md5</primary>
1645         </indexterm>
1646         <literal><function>md5(<parameter>string</parameter>)</function></literal>
1647        </entry>
1648        <entry><type>text</type></entry>
1649        <entry>
1650         Calculates the MD5 hash of <parameter>string</parameter>,
1651         returning the result in hexadecimal
1652        </entry>
1653        <entry><literal>md5('abc')</literal></entry>
1654        <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1655       </row>
1656
1657       <row>
1658        <entry>
1659         <indexterm>
1660          <primary>pg_client_encoding</primary>
1661         </indexterm>
1662         <literal><function>pg_client_encoding()</function></literal>
1663        </entry>
1664        <entry><type>name</type></entry>
1665        <entry>
1666         Current client encoding name
1667        </entry>
1668        <entry><literal>pg_client_encoding()</literal></entry>
1669        <entry><literal>SQL_ASCII</literal></entry>
1670       </row>
1671
1672       <row>
1673        <entry>
1674         <indexterm>
1675          <primary>quote_ident</primary>
1676         </indexterm>
1677         <literal><function>quote_ident(<parameter>string</parameter> <type>text</type>)</function></literal>
1678        </entry>
1679        <entry><type>text</type></entry>
1680        <entry>
1681         Return the given string suitably quoted to be used as an identifier
1682         in an <acronym>SQL</acronym> statement string.
1683         Quotes are added only if necessary (i.e., if the string contains
1684         non-identifier characters or would be case-folded).
1685         Embedded quotes are properly doubled.
1686         See also <xref linkend="plpgsql-quote-literal-example">.
1687        </entry>
1688        <entry><literal>quote_ident('Foo bar')</literal></entry>
1689        <entry><literal>"Foo bar"</literal></entry>
1690       </row>
1691
1692       <row>
1693        <entry>
1694         <indexterm>
1695          <primary>quote_literal</primary>
1696         </indexterm>
1697         <literal><function>quote_literal(<parameter>string</parameter> <type>text</type>)</function></literal>
1698        </entry>
1699        <entry><type>text</type></entry>
1700        <entry>
1701         Return the given string suitably quoted to be used as a string literal
1702         in an <acronym>SQL</acronym> statement string.
1703         Embedded single-quotes and backslashes are properly doubled.
1704         Note that <function>quote_literal</function> returns null on null
1705         input; if the argument might be null,
1706         <function>quote_nullable</function> is often more suitable.
1707         See also <xref linkend="plpgsql-quote-literal-example">.
1708        </entry>
1709        <entry><literal>quote_literal('O\'Reilly')</literal></entry>
1710        <entry><literal>'O''Reilly'</literal></entry>
1711       </row>
1712
1713       <row>
1714        <entry><literal><function>quote_literal(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1715        <entry><type>text</type></entry>
1716        <entry>
1717         Coerce the given value to text and then quote it as a literal.
1718         Embedded single-quotes and backslashes are properly doubled.
1719        </entry>
1720        <entry><literal>quote_literal(42.5)</literal></entry>
1721        <entry><literal>'42.5'</literal></entry>
1722       </row>
1723
1724       <row>
1725        <entry>
1726         <indexterm>
1727          <primary>quote_nullable</primary>
1728         </indexterm>
1729         <literal><function>quote_nullable(<parameter>string</parameter> <type>text</type>)</function></literal>
1730        </entry>
1731        <entry><type>text</type></entry>
1732        <entry>
1733         Return the given string suitably quoted to be used as a string literal
1734         in an <acronym>SQL</acronym> statement string; or, if the argument
1735         is null, return <literal>NULL</>.
1736         Embedded single-quotes and backslashes are properly doubled.
1737         See also <xref linkend="plpgsql-quote-literal-example">.
1738        </entry>
1739        <entry><literal>quote_nullable(NULL)</literal></entry>
1740        <entry><literal>NULL</literal></entry>
1741       </row>
1742
1743       <row>
1744        <entry><literal><function>quote_nullable(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
1745        <entry><type>text</type></entry>
1746        <entry>
1747         Coerce the given value to text and then quote it as a literal;
1748         or, if the argument is null, return <literal>NULL</>.
1749         Embedded single-quotes and backslashes are properly doubled.
1750        </entry>
1751        <entry><literal>quote_nullable(42.5)</literal></entry>
1752        <entry><literal>'42.5'</literal></entry>
1753       </row>
1754
1755       <row>
1756        <entry>
1757         <indexterm>
1758          <primary>regexp_matches</primary>
1759         </indexterm>
1760         <literal><function>regexp_matches(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
1761        </entry>
1762        <entry><type>setof text[]</type></entry>
1763        <entry>
1764         Return all captured substrings resulting from matching a POSIX regular
1765         expression against the <parameter>string</parameter>. See
1766         <xref linkend="functions-posix-regexp"> for more information.
1767        </entry>
1768        <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
1769        <entry><literal>{bar,beque}</literal></entry>
1770       </row>
1771
1772       <row>
1773        <entry>
1774         <indexterm>
1775          <primary>regexp_replace</primary>
1776         </indexterm>
1777         <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>
1778        </entry>
1779        <entry><type>text</type></entry>
1780        <entry>
1781         Replace substring(s) matching a POSIX regular expression. See
1782         <xref linkend="functions-posix-regexp"> for more information.
1783        </entry>
1784        <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
1785        <entry><literal>ThM</literal></entry>
1786       </row>
1787
1788       <row>
1789        <entry>
1790         <indexterm>
1791          <primary>regexp_split_to_array</primary>
1792         </indexterm>
1793         <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>
1794        </entry>
1795        <entry><type>text[]</type></entry>
1796        <entry>
1797         Split <parameter>string</parameter> using a POSIX regular expression as
1798         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1799         information.
1800        </entry>
1801        <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
1802        <entry><literal>{hello,world}</literal></entry>
1803       </row>
1804
1805       <row>
1806        <entry>
1807         <indexterm>
1808          <primary>regexp_split_to_table</primary>
1809         </indexterm>
1810         <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>
1811        </entry>
1812        <entry><type>setof text</type></entry>
1813        <entry>
1814         Split <parameter>string</parameter> using a POSIX regular expression as
1815         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1816         information.
1817        </entry>
1818        <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
1819        <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
1820       </row>
1821
1822       <row>
1823        <entry>
1824         <indexterm>
1825          <primary>repeat</primary>
1826         </indexterm>
1827         <literal><function>repeat(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</function></literal>
1828        </entry>
1829        <entry><type>text</type></entry>
1830        <entry>Repeat <parameter>string</parameter> the specified
1831        <parameter>number</parameter> of times</entry>
1832        <entry><literal>repeat('Pg', 4)</literal></entry>
1833        <entry><literal>PgPgPgPg</literal></entry>
1834       </row>
1835
1836       <row>
1837        <entry>
1838         <indexterm>
1839          <primary>replace</primary>
1840         </indexterm>
1841         <literal><function>replace(<parameter>string</parameter> <type>text</type>,
1842         <parameter>from</parameter> <type>text</type>,
1843         <parameter>to</parameter> <type>text</type>)</function></literal>
1844        </entry>
1845        <entry><type>text</type></entry>
1846        <entry>Replace all occurrences in <parameter>string</parameter> of substring
1847         <parameter>from</parameter> with substring <parameter>to</parameter>
1848        </entry>
1849        <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
1850        <entry><literal>abXXefabXXef</literal></entry>
1851       </row>
1852
1853       <row>
1854        <entry>
1855         <indexterm>
1856          <primary>reverse</primary>
1857         </indexterm>
1858         <literal><function>reverse(<parameter>str</parameter>)</function></literal>
1859        </entry>
1860        <entry><type>text</type></entry>
1861        <entry>
1862         Return reversed string.
1863        </entry>
1864        <entry><literal>reverse('abcde')</literal></entry>
1865        <entry><literal>edcba</literal></entry>
1866       </row>
1867
1868       <row>
1869        <entry>
1870         <indexterm>
1871          <primary>right</primary>
1872         </indexterm>
1873         <literal><function>right(<parameter>str</parameter> <type>text</type>,
1874          <parameter>n</parameter> <type>int</type>)</function></literal>
1875        </entry>
1876        <entry><type>text</type></entry>
1877        <entry>
1878         Return last <replaceable>n</> characters in the string. When <replaceable>n</>
1879         is negative, return all but first |<replaceable>n</>| characters.
1880        </entry>
1881        <entry><literal>right('abcde', 2)</literal></entry>
1882        <entry><literal>de</literal></entry>
1883       </row>
1884
1885       <row>
1886        <entry>
1887         <indexterm>
1888          <primary>rpad</primary>
1889         </indexterm>
1890         <literal><function>rpad(<parameter>string</parameter> <type>text</type>,
1891         <parameter>length</parameter> <type>int</type>
1892         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1893        </entry>
1894        <entry><type>text</type></entry>
1895        <entry>
1896         Fill up the <parameter>string</parameter> to length
1897         <parameter>length</parameter> by appending the characters
1898         <parameter>fill</parameter> (a space by default).  If the
1899         <parameter>string</parameter> is already longer than
1900         <parameter>length</parameter> then it is truncated.
1901        </entry>
1902        <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
1903        <entry><literal>hixyx</literal></entry>
1904       </row>
1905
1906       <row>
1907        <entry>
1908         <indexterm>
1909          <primary>rtrim</primary>
1910         </indexterm>
1911         <literal><function>rtrim(<parameter>string</parameter> <type>text</type>
1912          <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1913        </entry>
1914        <entry><type>text</type></entry>
1915        <entry>
1916         Remove the longest string containing only characters from
1917         <parameter>characters</parameter> (a space by default) from the end of
1918         <parameter>string</parameter>
1919        </entry>
1920        <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
1921        <entry><literal>trim</literal></entry>
1922       </row>
1923
1924       <row>
1925        <entry>
1926         <indexterm>
1927          <primary>split_part</primary>
1928         </indexterm>
1929         <literal><function>split_part(<parameter>string</parameter> <type>text</type>,
1930         <parameter>delimiter</parameter> <type>text</type>,
1931         <parameter>field</parameter> <type>int</type>)</function></literal>
1932        </entry>
1933        <entry><type>text</type></entry>
1934        <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1935         and return the given field (counting from one)
1936        </entry>
1937        <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
1938        <entry><literal>def</literal></entry>
1939       </row>
1940
1941       <row>
1942        <entry>
1943         <indexterm>
1944          <primary>strpos</primary>
1945         </indexterm>
1946         <literal><function>strpos(<parameter>string</parameter>, <parameter>substring</parameter>)</function></literal>
1947        </entry>
1948        <entry><type>int</type></entry>
1949        <entry>
1950         Location of specified substring (same as
1951         <literal>position(<parameter>substring</parameter> in
1952          <parameter>string</parameter>)</literal>, but note the reversed
1953         argument order)
1954        </entry>
1955        <entry><literal>strpos('high', 'ig')</literal></entry>
1956        <entry><literal>2</literal></entry>
1957       </row>
1958
1959       <row>
1960        <entry>
1961         <indexterm>
1962          <primary>substr</primary>
1963         </indexterm>
1964         <literal><function>substr(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</function></literal>
1965        </entry>
1966        <entry><type>text</type></entry>
1967        <entry>
1968         Extract substring (same as
1969         <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
1970        </entry>
1971        <entry><literal>substr('alphabet', 3, 2)</literal></entry>
1972        <entry><literal>ph</literal></entry>
1973       </row>
1974
1975       <row>
1976        <entry>
1977         <indexterm>
1978          <primary>to_ascii</primary>
1979         </indexterm>
1980         <literal><function>to_ascii(<parameter>string</parameter> <type>text</type>
1981         <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</function></literal>
1982        </entry>
1983        <entry><type>text</type></entry>
1984        <entry>
1985        Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
1986        (only supports conversion from  <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
1987        and <literal>WIN1250</> encodings)
1988        </entry>
1989        <entry><literal>to_ascii('Karel')</literal></entry>
1990        <entry><literal>Karel</literal></entry>
1991       </row>
1992
1993       <row>
1994        <entry>
1995         <indexterm>
1996          <primary>to_hex</primary>
1997         </indexterm>
1998         <literal><function>to_hex(<parameter>number</parameter> <type>int</type>
1999         or <type>bigint</type>)</function></literal>
2000        </entry>
2001        <entry><type>text</type></entry>
2002        <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
2003         representation
2004        </entry>
2005        <entry><literal>to_hex(2147483647)</literal></entry>
2006        <entry><literal>7fffffff</literal></entry>
2007       </row>
2008
2009       <row>
2010        <entry>
2011         <indexterm>
2012          <primary>translate</primary>
2013         </indexterm>
2014         <literal><function>translate(<parameter>string</parameter> <type>text</type>,
2015         <parameter>from</parameter> <type>text</type>,
2016         <parameter>to</parameter> <type>text</type>)</function></literal>
2017        </entry>
2018        <entry><type>text</type></entry>
2019        <entry>
2020         Any character in <parameter>string</parameter> that matches a
2021         character in the <parameter>from</parameter> set is replaced by
2022         the corresponding character in the <parameter>to</parameter>
2023         set. If <parameter>from</parameter> is longer than
2024         <parameter>to</parameter>, occurrences of the extra characters in
2025         <parameter>from</parameter> are removed.
2026        </entry>
2027        <entry><literal>translate('12345', '143', 'ax')</literal></entry>
2028        <entry><literal>a2x5</literal></entry>
2029       </row>
2030
2031      </tbody>
2032     </tgroup>
2033    </table>
2034
2035    <para>
2036    See also the aggregate function <function>string_agg</function> in
2037    <xref linkend="functions-aggregate">.
2038    </para>
2039
2040    <table id="conversion-names">
2041     <title>Built-in Conversions</title>
2042     <tgroup cols="3">
2043      <thead>
2044       <row>
2045        <entry>Conversion Name
2046         <footnote>
2047          <para>
2048           The conversion names follow a standard naming scheme: The
2049           official name of the source encoding with all
2050           non-alphanumeric characters replaced by underscores, followed
2051           by <literal>_to_</literal>, followed by the similarly processed
2052           destination encoding name. Therefore, the names might deviate
2053           from the customary encoding names.
2054          </para>
2055         </footnote>
2056        </entry>
2057        <entry>Source Encoding</entry>
2058        <entry>Destination Encoding</entry>
2059       </row>
2060      </thead>
2061
2062      <tbody>
2063       <row>
2064        <entry><literal>ascii_to_mic</literal></entry>
2065        <entry><literal>SQL_ASCII</literal></entry>
2066        <entry><literal>MULE_INTERNAL</literal></entry>
2067       </row>
2068
2069       <row>
2070        <entry><literal>ascii_to_utf8</literal></entry>
2071        <entry><literal>SQL_ASCII</literal></entry>
2072        <entry><literal>UTF8</literal></entry>
2073       </row>
2074
2075       <row>
2076        <entry><literal>big5_to_euc_tw</literal></entry>
2077        <entry><literal>BIG5</literal></entry>
2078        <entry><literal>EUC_TW</literal></entry>
2079       </row>
2080
2081       <row>
2082        <entry><literal>big5_to_mic</literal></entry>
2083        <entry><literal>BIG5</literal></entry>
2084        <entry><literal>MULE_INTERNAL</literal></entry>
2085       </row>
2086
2087       <row>
2088        <entry><literal>big5_to_utf8</literal></entry>
2089        <entry><literal>BIG5</literal></entry>
2090        <entry><literal>UTF8</literal></entry>
2091       </row>
2092
2093       <row>
2094        <entry><literal>euc_cn_to_mic</literal></entry>
2095        <entry><literal>EUC_CN</literal></entry>
2096        <entry><literal>MULE_INTERNAL</literal></entry>
2097       </row>
2098
2099       <row>
2100        <entry><literal>euc_cn_to_utf8</literal></entry>
2101        <entry><literal>EUC_CN</literal></entry>
2102        <entry><literal>UTF8</literal></entry>
2103       </row>
2104
2105       <row>
2106        <entry><literal>euc_jp_to_mic</literal></entry>
2107        <entry><literal>EUC_JP</literal></entry>
2108        <entry><literal>MULE_INTERNAL</literal></entry>
2109       </row>
2110
2111       <row>
2112        <entry><literal>euc_jp_to_sjis</literal></entry>
2113        <entry><literal>EUC_JP</literal></entry>
2114        <entry><literal>SJIS</literal></entry>
2115       </row>
2116
2117       <row>
2118        <entry><literal>euc_jp_to_utf8</literal></entry>
2119        <entry><literal>EUC_JP</literal></entry>
2120        <entry><literal>UTF8</literal></entry>
2121       </row>
2122
2123       <row>
2124        <entry><literal>euc_kr_to_mic</literal></entry>
2125        <entry><literal>EUC_KR</literal></entry>
2126        <entry><literal>MULE_INTERNAL</literal></entry>
2127       </row>
2128
2129       <row>
2130        <entry><literal>euc_kr_to_utf8</literal></entry>
2131        <entry><literal>EUC_KR</literal></entry>
2132        <entry><literal>UTF8</literal></entry>
2133       </row>
2134
2135       <row>
2136        <entry><literal>euc_tw_to_big5</literal></entry>
2137        <entry><literal>EUC_TW</literal></entry>
2138        <entry><literal>BIG5</literal></entry>
2139       </row>
2140
2141       <row>
2142        <entry><literal>euc_tw_to_mic</literal></entry>
2143        <entry><literal>EUC_TW</literal></entry>
2144        <entry><literal>MULE_INTERNAL</literal></entry>
2145       </row>
2146
2147       <row>
2148        <entry><literal>euc_tw_to_utf8</literal></entry>
2149        <entry><literal>EUC_TW</literal></entry>
2150        <entry><literal>UTF8</literal></entry>
2151       </row>
2152
2153       <row>
2154        <entry><literal>gb18030_to_utf8</literal></entry>
2155        <entry><literal>GB18030</literal></entry>
2156        <entry><literal>UTF8</literal></entry>
2157       </row>
2158
2159       <row>
2160        <entry><literal>gbk_to_utf8</literal></entry>
2161        <entry><literal>GBK</literal></entry>
2162        <entry><literal>UTF8</literal></entry>
2163       </row>
2164
2165       <row>
2166        <entry><literal>iso_8859_10_to_utf8</literal></entry>
2167        <entry><literal>LATIN6</literal></entry>
2168        <entry><literal>UTF8</literal></entry>
2169       </row>
2170
2171       <row>
2172        <entry><literal>iso_8859_13_to_utf8</literal></entry>
2173        <entry><literal>LATIN7</literal></entry>
2174        <entry><literal>UTF8</literal></entry>
2175       </row>
2176
2177       <row>
2178        <entry><literal>iso_8859_14_to_utf8</literal></entry>
2179        <entry><literal>LATIN8</literal></entry>
2180        <entry><literal>UTF8</literal></entry>
2181       </row>
2182
2183       <row>
2184        <entry><literal>iso_8859_15_to_utf8</literal></entry>
2185        <entry><literal>LATIN9</literal></entry>
2186        <entry><literal>UTF8</literal></entry>
2187       </row>
2188
2189       <row>
2190        <entry><literal>iso_8859_16_to_utf8</literal></entry>
2191        <entry><literal>LATIN10</literal></entry>
2192        <entry><literal>UTF8</literal></entry>
2193       </row>
2194
2195       <row>
2196        <entry><literal>iso_8859_1_to_mic</literal></entry>
2197        <entry><literal>LATIN1</literal></entry>
2198        <entry><literal>MULE_INTERNAL</literal></entry>
2199       </row>
2200
2201       <row>
2202        <entry><literal>iso_8859_1_to_utf8</literal></entry>
2203        <entry><literal>LATIN1</literal></entry>
2204        <entry><literal>UTF8</literal></entry>
2205       </row>
2206
2207       <row>
2208        <entry><literal>iso_8859_2_to_mic</literal></entry>
2209        <entry><literal>LATIN2</literal></entry>
2210        <entry><literal>MULE_INTERNAL</literal></entry>
2211       </row>
2212
2213       <row>
2214        <entry><literal>iso_8859_2_to_utf8</literal></entry>
2215        <entry><literal>LATIN2</literal></entry>
2216        <entry><literal>UTF8</literal></entry>
2217       </row>
2218
2219       <row>
2220        <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
2221        <entry><literal>LATIN2</literal></entry>
2222        <entry><literal>WIN1250</literal></entry>
2223       </row>
2224
2225       <row>
2226        <entry><literal>iso_8859_3_to_mic</literal></entry>
2227        <entry><literal>LATIN3</literal></entry>
2228        <entry><literal>MULE_INTERNAL</literal></entry>
2229       </row>
2230
2231       <row>
2232        <entry><literal>iso_8859_3_to_utf8</literal></entry>
2233        <entry><literal>LATIN3</literal></entry>
2234        <entry><literal>UTF8</literal></entry>
2235       </row>
2236
2237       <row>
2238        <entry><literal>iso_8859_4_to_mic</literal></entry>
2239        <entry><literal>LATIN4</literal></entry>
2240        <entry><literal>MULE_INTERNAL</literal></entry>
2241       </row>
2242
2243       <row>
2244        <entry><literal>iso_8859_4_to_utf8</literal></entry>
2245        <entry><literal>LATIN4</literal></entry>
2246        <entry><literal>UTF8</literal></entry>
2247       </row>
2248
2249       <row>
2250        <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
2251        <entry><literal>ISO_8859_5</literal></entry>
2252        <entry><literal>KOI8R</literal></entry>
2253       </row>
2254
2255       <row>
2256        <entry><literal>iso_8859_5_to_mic</literal></entry>
2257        <entry><literal>ISO_8859_5</literal></entry>
2258        <entry><literal>MULE_INTERNAL</literal></entry>
2259       </row>
2260
2261       <row>
2262        <entry><literal>iso_8859_5_to_utf8</literal></entry>
2263        <entry><literal>ISO_8859_5</literal></entry>
2264        <entry><literal>UTF8</literal></entry>
2265       </row>
2266
2267       <row>
2268        <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
2269        <entry><literal>ISO_8859_5</literal></entry>
2270        <entry><literal>WIN1251</literal></entry>
2271       </row>
2272
2273       <row>
2274        <entry><literal>iso_8859_5_to_windows_866</literal></entry>
2275        <entry><literal>ISO_8859_5</literal></entry>
2276        <entry><literal>WIN866</literal></entry>
2277       </row>
2278
2279       <row>
2280        <entry><literal>iso_8859_6_to_utf8</literal></entry>
2281        <entry><literal>ISO_8859_6</literal></entry>
2282        <entry><literal>UTF8</literal></entry>
2283       </row>
2284
2285       <row>
2286        <entry><literal>iso_8859_7_to_utf8</literal></entry>
2287        <entry><literal>ISO_8859_7</literal></entry>
2288        <entry><literal>UTF8</literal></entry>
2289       </row>
2290
2291       <row>
2292        <entry><literal>iso_8859_8_to_utf8</literal></entry>
2293        <entry><literal>ISO_8859_8</literal></entry>
2294        <entry><literal>UTF8</literal></entry>
2295       </row>
2296
2297       <row>
2298        <entry><literal>iso_8859_9_to_utf8</literal></entry>
2299        <entry><literal>LATIN5</literal></entry>
2300        <entry><literal>UTF8</literal></entry>
2301       </row>
2302
2303       <row>
2304        <entry><literal>johab_to_utf8</literal></entry>
2305        <entry><literal>JOHAB</literal></entry>
2306        <entry><literal>UTF8</literal></entry>
2307       </row>
2308
2309       <row>
2310        <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
2311        <entry><literal>KOI8R</literal></entry>
2312        <entry><literal>ISO_8859_5</literal></entry>
2313       </row>
2314
2315       <row>
2316        <entry><literal>koi8_r_to_mic</literal></entry>
2317        <entry><literal>KOI8R</literal></entry>
2318        <entry><literal>MULE_INTERNAL</literal></entry>
2319       </row>
2320
2321       <row>
2322        <entry><literal>koi8_r_to_utf8</literal></entry>
2323        <entry><literal>KOI8R</literal></entry>
2324        <entry><literal>UTF8</literal></entry>
2325       </row>
2326
2327       <row>
2328        <entry><literal>koi8_r_to_windows_1251</literal></entry>
2329        <entry><literal>KOI8R</literal></entry>
2330        <entry><literal>WIN1251</literal></entry>
2331       </row>
2332
2333       <row>
2334        <entry><literal>koi8_r_to_windows_866</literal></entry>
2335        <entry><literal>KOI8R</literal></entry>
2336        <entry><literal>WIN866</literal></entry>
2337       </row>
2338
2339       <row>
2340        <entry><literal>koi8_u_to_utf8</literal></entry>
2341        <entry><literal>KOI8U</literal></entry>
2342        <entry><literal>UTF8</literal></entry>
2343       </row>
2344
2345       <row>
2346        <entry><literal>mic_to_ascii</literal></entry>
2347        <entry><literal>MULE_INTERNAL</literal></entry>
2348        <entry><literal>SQL_ASCII</literal></entry>
2349       </row>
2350
2351       <row>
2352        <entry><literal>mic_to_big5</literal></entry>
2353        <entry><literal>MULE_INTERNAL</literal></entry>
2354        <entry><literal>BIG5</literal></entry>
2355       </row>
2356
2357       <row>
2358        <entry><literal>mic_to_euc_cn</literal></entry>
2359        <entry><literal>MULE_INTERNAL</literal></entry>
2360        <entry><literal>EUC_CN</literal></entry>
2361       </row>
2362
2363       <row>
2364        <entry><literal>mic_to_euc_jp</literal></entry>
2365        <entry><literal>MULE_INTERNAL</literal></entry>
2366        <entry><literal>EUC_JP</literal></entry>
2367       </row>
2368
2369       <row>
2370        <entry><literal>mic_to_euc_kr</literal></entry>
2371        <entry><literal>MULE_INTERNAL</literal></entry>
2372        <entry><literal>EUC_KR</literal></entry>
2373       </row>
2374
2375       <row>
2376        <entry><literal>mic_to_euc_tw</literal></entry>
2377        <entry><literal>MULE_INTERNAL</literal></entry>
2378        <entry><literal>EUC_TW</literal></entry>
2379       </row>
2380
2381       <row>
2382        <entry><literal>mic_to_iso_8859_1</literal></entry>
2383        <entry><literal>MULE_INTERNAL</literal></entry>
2384        <entry><literal>LATIN1</literal></entry>
2385       </row>
2386
2387       <row>
2388        <entry><literal>mic_to_iso_8859_2</literal></entry>
2389        <entry><literal>MULE_INTERNAL</literal></entry>
2390        <entry><literal>LATIN2</literal></entry>
2391       </row>
2392
2393       <row>
2394        <entry><literal>mic_to_iso_8859_3</literal></entry>
2395        <entry><literal>MULE_INTERNAL</literal></entry>
2396        <entry><literal>LATIN3</literal></entry>
2397       </row>
2398
2399       <row>
2400        <entry><literal>mic_to_iso_8859_4</literal></entry>
2401        <entry><literal>MULE_INTERNAL</literal></entry>
2402        <entry><literal>LATIN4</literal></entry>
2403       </row>
2404
2405       <row>
2406        <entry><literal>mic_to_iso_8859_5</literal></entry>
2407        <entry><literal>MULE_INTERNAL</literal></entry>
2408        <entry><literal>ISO_8859_5</literal></entry>
2409       </row>
2410
2411       <row>
2412        <entry><literal>mic_to_koi8_r</literal></entry>
2413        <entry><literal>MULE_INTERNAL</literal></entry>
2414        <entry><literal>KOI8R</literal></entry>
2415       </row>
2416
2417       <row>
2418        <entry><literal>mic_to_sjis</literal></entry>
2419        <entry><literal>MULE_INTERNAL</literal></entry>
2420        <entry><literal>SJIS</literal></entry>
2421       </row>
2422
2423       <row>
2424        <entry><literal>mic_to_windows_1250</literal></entry>
2425        <entry><literal>MULE_INTERNAL</literal></entry>
2426        <entry><literal>WIN1250</literal></entry>
2427       </row>
2428
2429       <row>
2430        <entry><literal>mic_to_windows_1251</literal></entry>
2431        <entry><literal>MULE_INTERNAL</literal></entry>
2432        <entry><literal>WIN1251</literal></entry>
2433       </row>
2434
2435       <row>
2436        <entry><literal>mic_to_windows_866</literal></entry>
2437        <entry><literal>MULE_INTERNAL</literal></entry>
2438        <entry><literal>WIN866</literal></entry>
2439       </row>
2440
2441       <row>
2442        <entry><literal>sjis_to_euc_jp</literal></entry>
2443        <entry><literal>SJIS</literal></entry>
2444        <entry><literal>EUC_JP</literal></entry>
2445       </row>
2446
2447       <row>
2448        <entry><literal>sjis_to_mic</literal></entry>
2449        <entry><literal>SJIS</literal></entry>
2450        <entry><literal>MULE_INTERNAL</literal></entry>
2451       </row>
2452
2453       <row>
2454        <entry><literal>sjis_to_utf8</literal></entry>
2455        <entry><literal>SJIS</literal></entry>
2456        <entry><literal>UTF8</literal></entry>
2457       </row>
2458
2459       <row>
2460        <entry><literal>tcvn_to_utf8</literal></entry>
2461        <entry><literal>WIN1258</literal></entry>
2462        <entry><literal>UTF8</literal></entry>
2463       </row>
2464
2465       <row>
2466        <entry><literal>uhc_to_utf8</literal></entry>
2467        <entry><literal>UHC</literal></entry>
2468        <entry><literal>UTF8</literal></entry>
2469       </row>
2470
2471       <row>
2472        <entry><literal>utf8_to_ascii</literal></entry>
2473        <entry><literal>UTF8</literal></entry>
2474        <entry><literal>SQL_ASCII</literal></entry>
2475       </row>
2476
2477       <row>
2478        <entry><literal>utf8_to_big5</literal></entry>
2479        <entry><literal>UTF8</literal></entry>
2480        <entry><literal>BIG5</literal></entry>
2481       </row>
2482
2483       <row>
2484        <entry><literal>utf8_to_euc_cn</literal></entry>
2485        <entry><literal>UTF8</literal></entry>
2486        <entry><literal>EUC_CN</literal></entry>
2487       </row>
2488
2489       <row>
2490        <entry><literal>utf8_to_euc_jp</literal></entry>
2491        <entry><literal>UTF8</literal></entry>
2492        <entry><literal>EUC_JP</literal></entry>
2493       </row>
2494
2495       <row>
2496        <entry><literal>utf8_to_euc_kr</literal></entry>
2497        <entry><literal>UTF8</literal></entry>
2498        <entry><literal>EUC_KR</literal></entry>
2499       </row>
2500
2501       <row>
2502        <entry><literal>utf8_to_euc_tw</literal></entry>
2503        <entry><literal>UTF8</literal></entry>
2504        <entry><literal>EUC_TW</literal></entry>
2505       </row>
2506
2507       <row>
2508        <entry><literal>utf8_to_gb18030</literal></entry>
2509        <entry><literal>UTF8</literal></entry>
2510        <entry><literal>GB18030</literal></entry>
2511       </row>
2512
2513       <row>
2514        <entry><literal>utf8_to_gbk</literal></entry>
2515        <entry><literal>UTF8</literal></entry>
2516        <entry><literal>GBK</literal></entry>
2517       </row>
2518
2519       <row>
2520        <entry><literal>utf8_to_iso_8859_1</literal></entry>
2521        <entry><literal>UTF8</literal></entry>
2522        <entry><literal>LATIN1</literal></entry>
2523       </row>
2524
2525       <row>
2526        <entry><literal>utf8_to_iso_8859_10</literal></entry>
2527        <entry><literal>UTF8</literal></entry>
2528        <entry><literal>LATIN6</literal></entry>
2529       </row>
2530
2531       <row>
2532        <entry><literal>utf8_to_iso_8859_13</literal></entry>
2533        <entry><literal>UTF8</literal></entry>
2534        <entry><literal>LATIN7</literal></entry>
2535       </row>
2536
2537       <row>
2538        <entry><literal>utf8_to_iso_8859_14</literal></entry>
2539        <entry><literal>UTF8</literal></entry>
2540        <entry><literal>LATIN8</literal></entry>
2541       </row>
2542
2543       <row>
2544        <entry><literal>utf8_to_iso_8859_15</literal></entry>
2545        <entry><literal>UTF8</literal></entry>
2546        <entry><literal>LATIN9</literal></entry>
2547       </row>
2548
2549       <row>
2550        <entry><literal>utf8_to_iso_8859_16</literal></entry>
2551        <entry><literal>UTF8</literal></entry>
2552        <entry><literal>LATIN10</literal></entry>
2553       </row>
2554
2555       <row>
2556        <entry><literal>utf8_to_iso_8859_2</literal></entry>
2557        <entry><literal>UTF8</literal></entry>
2558        <entry><literal>LATIN2</literal></entry>
2559       </row>
2560
2561       <row>
2562        <entry><literal>utf8_to_iso_8859_3</literal></entry>
2563        <entry><literal>UTF8</literal></entry>
2564        <entry><literal>LATIN3</literal></entry>
2565       </row>
2566
2567       <row>
2568        <entry><literal>utf8_to_iso_8859_4</literal></entry>
2569        <entry><literal>UTF8</literal></entry>
2570        <entry><literal>LATIN4</literal></entry>
2571       </row>
2572
2573       <row>
2574        <entry><literal>utf8_to_iso_8859_5</literal></entry>
2575        <entry><literal>UTF8</literal></entry>
2576        <entry><literal>ISO_8859_5</literal></entry>
2577       </row>
2578
2579       <row>
2580        <entry><literal>utf8_to_iso_8859_6</literal></entry>
2581        <entry><literal>UTF8</literal></entry>
2582        <entry><literal>ISO_8859_6</literal></entry>
2583       </row>
2584
2585       <row>
2586        <entry><literal>utf8_to_iso_8859_7</literal></entry>
2587        <entry><literal>UTF8</literal></entry>
2588        <entry><literal>ISO_8859_7</literal></entry>
2589       </row>
2590
2591       <row>
2592        <entry><literal>utf8_to_iso_8859_8</literal></entry>
2593        <entry><literal>UTF8</literal></entry>
2594        <entry><literal>ISO_8859_8</literal></entry>
2595       </row>
2596
2597       <row>
2598        <entry><literal>utf8_to_iso_8859_9</literal></entry>
2599        <entry><literal>UTF8</literal></entry>
2600        <entry><literal>LATIN5</literal></entry>
2601       </row>
2602
2603       <row>
2604        <entry><literal>utf8_to_johab</literal></entry>
2605        <entry><literal>UTF8</literal></entry>
2606        <entry><literal>JOHAB</literal></entry>
2607       </row>
2608
2609       <row>
2610        <entry><literal>utf8_to_koi8_r</literal></entry>
2611        <entry><literal>UTF8</literal></entry>
2612        <entry><literal>KOI8R</literal></entry>
2613       </row>
2614
2615       <row>
2616        <entry><literal>utf8_to_koi8_u</literal></entry>
2617        <entry><literal>UTF8</literal></entry>
2618        <entry><literal>KOI8U</literal></entry>
2619       </row>
2620
2621       <row>
2622        <entry><literal>utf8_to_sjis</literal></entry>
2623        <entry><literal>UTF8</literal></entry>
2624        <entry><literal>SJIS</literal></entry>
2625       </row>
2626
2627       <row>
2628        <entry><literal>utf8_to_tcvn</literal></entry>
2629        <entry><literal>UTF8</literal></entry>
2630        <entry><literal>WIN1258</literal></entry>
2631       </row>
2632
2633       <row>
2634        <entry><literal>utf8_to_uhc</literal></entry>
2635        <entry><literal>UTF8</literal></entry>
2636        <entry><literal>UHC</literal></entry>
2637       </row>
2638
2639       <row>
2640        <entry><literal>utf8_to_windows_1250</literal></entry>
2641        <entry><literal>UTF8</literal></entry>
2642        <entry><literal>WIN1250</literal></entry>
2643       </row>
2644
2645       <row>
2646        <entry><literal>utf8_to_windows_1251</literal></entry>
2647        <entry><literal>UTF8</literal></entry>
2648        <entry><literal>WIN1251</literal></entry>
2649       </row>
2650
2651       <row>
2652        <entry><literal>utf8_to_windows_1252</literal></entry>
2653        <entry><literal>UTF8</literal></entry>
2654        <entry><literal>WIN1252</literal></entry>
2655       </row>
2656
2657       <row>
2658        <entry><literal>utf8_to_windows_1253</literal></entry>
2659        <entry><literal>UTF8</literal></entry>
2660        <entry><literal>WIN1253</literal></entry>
2661       </row>
2662
2663       <row>
2664        <entry><literal>utf8_to_windows_1254</literal></entry>
2665        <entry><literal>UTF8</literal></entry>
2666        <entry><literal>WIN1254</literal></entry>
2667       </row>
2668
2669       <row>
2670        <entry><literal>utf8_to_windows_1255</literal></entry>
2671        <entry><literal>UTF8</literal></entry>
2672        <entry><literal>WIN1255</literal></entry>
2673       </row>
2674
2675       <row>
2676        <entry><literal>utf8_to_windows_1256</literal></entry>
2677        <entry><literal>UTF8</literal></entry>
2678        <entry><literal>WIN1256</literal></entry>
2679       </row>
2680
2681       <row>
2682        <entry><literal>utf8_to_windows_1257</literal></entry>
2683        <entry><literal>UTF8</literal></entry>
2684        <entry><literal>WIN1257</literal></entry>
2685       </row>
2686
2687       <row>
2688        <entry><literal>utf8_to_windows_866</literal></entry>
2689        <entry><literal>UTF8</literal></entry>
2690        <entry><literal>WIN866</literal></entry>
2691       </row>
2692
2693       <row>
2694        <entry><literal>utf8_to_windows_874</literal></entry>
2695        <entry><literal>UTF8</literal></entry>
2696        <entry><literal>WIN874</literal></entry>
2697       </row>
2698
2699       <row>
2700        <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
2701        <entry><literal>WIN1250</literal></entry>
2702        <entry><literal>LATIN2</literal></entry>
2703       </row>
2704
2705       <row>
2706        <entry><literal>windows_1250_to_mic</literal></entry>
2707        <entry><literal>WIN1250</literal></entry>
2708        <entry><literal>MULE_INTERNAL</literal></entry>
2709       </row>
2710
2711       <row>
2712        <entry><literal>windows_1250_to_utf8</literal></entry>
2713        <entry><literal>WIN1250</literal></entry>
2714        <entry><literal>UTF8</literal></entry>
2715       </row>
2716
2717       <row>
2718        <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
2719        <entry><literal>WIN1251</literal></entry>
2720        <entry><literal>ISO_8859_5</literal></entry>
2721       </row>
2722
2723       <row>
2724        <entry><literal>windows_1251_to_koi8_r</literal></entry>
2725        <entry><literal>WIN1251</literal></entry>
2726        <entry><literal>KOI8R</literal></entry>
2727       </row>
2728
2729       <row>
2730        <entry><literal>windows_1251_to_mic</literal></entry>
2731        <entry><literal>WIN1251</literal></entry>
2732        <entry><literal>MULE_INTERNAL</literal></entry>
2733       </row>
2734
2735       <row>
2736        <entry><literal>windows_1251_to_utf8</literal></entry>
2737        <entry><literal>WIN1251</literal></entry>
2738        <entry><literal>UTF8</literal></entry>
2739       </row>
2740
2741       <row>
2742        <entry><literal>windows_1251_to_windows_866</literal></entry>
2743        <entry><literal>WIN1251</literal></entry>
2744        <entry><literal>WIN866</literal></entry>
2745       </row>
2746
2747       <row>
2748        <entry><literal>windows_1252_to_utf8</literal></entry>
2749        <entry><literal>WIN1252</literal></entry>
2750        <entry><literal>UTF8</literal></entry>
2751       </row>
2752
2753       <row>
2754        <entry><literal>windows_1256_to_utf8</literal></entry>
2755        <entry><literal>WIN1256</literal></entry>
2756        <entry><literal>UTF8</literal></entry>
2757       </row>
2758
2759       <row>
2760        <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2761        <entry><literal>WIN866</literal></entry>
2762        <entry><literal>ISO_8859_5</literal></entry>
2763       </row>
2764
2765       <row>
2766        <entry><literal>windows_866_to_koi8_r</literal></entry>
2767        <entry><literal>WIN866</literal></entry>
2768        <entry><literal>KOI8R</literal></entry>
2769       </row>
2770
2771       <row>
2772        <entry><literal>windows_866_to_mic</literal></entry>
2773        <entry><literal>WIN866</literal></entry>
2774        <entry><literal>MULE_INTERNAL</literal></entry>
2775       </row>
2776
2777       <row>
2778        <entry><literal>windows_866_to_utf8</literal></entry>
2779        <entry><literal>WIN866</literal></entry>
2780        <entry><literal>UTF8</literal></entry>
2781       </row>
2782
2783       <row>
2784        <entry><literal>windows_866_to_windows_1251</literal></entry>
2785        <entry><literal>WIN866</literal></entry>
2786        <entry><literal>WIN</literal></entry>
2787       </row>
2788
2789       <row>
2790        <entry><literal>windows_874_to_utf8</literal></entry>
2791        <entry><literal>WIN874</literal></entry>
2792        <entry><literal>UTF8</literal></entry>
2793       </row>
2794
2795       <row>
2796        <entry><literal>euc_jis_2004_to_utf8</literal></entry>
2797        <entry><literal>EUC_JIS_2004</literal></entry>
2798        <entry><literal>UTF8</literal></entry>
2799       </row>
2800
2801       <row>
2802        <entry><literal>ut8_to_euc_jis_2004</literal></entry>
2803        <entry><literal>UTF8</literal></entry>
2804        <entry><literal>EUC_JIS_2004</literal></entry>
2805       </row>
2806
2807       <row>
2808        <entry><literal>shift_jis_2004_to_utf8</literal></entry>
2809        <entry><literal>SHIFT_JIS_2004</literal></entry>
2810        <entry><literal>UTF8</literal></entry>
2811       </row>
2812
2813       <row>
2814        <entry><literal>ut8_to_shift_jis_2004</literal></entry>
2815        <entry><literal>UTF8</literal></entry>
2816        <entry><literal>SHIFT_JIS_2004</literal></entry>
2817       </row>
2818
2819       <row>
2820        <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
2821        <entry><literal>EUC_JIS_2004</literal></entry>
2822        <entry><literal>SHIFT_JIS_2004</literal></entry>
2823       </row>
2824
2825       <row>
2826        <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
2827        <entry><literal>SHIFT_JIS_2004</literal></entry>
2828        <entry><literal>EUC_JIS_2004</literal></entry>
2829       </row>
2830
2831      </tbody>
2832     </tgroup>
2833    </table>
2834
2835   </sect1>
2836
2837
2838   <sect1 id="functions-binarystring">
2839    <title>Binary String Functions and Operators</title>
2840
2841    <indexterm zone="functions-binarystring">
2842     <primary>binary data</primary>
2843     <secondary>functions</secondary>
2844    </indexterm>
2845
2846    <para>
2847     This section describes functions and operators for examining and
2848     manipulating values of type <type>bytea</type>.
2849    </para>
2850
2851    <para>
2852     <acronym>SQL</acronym> defines some string functions that use
2853     key words, rather than commas, to separate
2854     arguments.  Details are in
2855     <xref linkend="functions-binarystring-sql">.
2856     <productname>PostgreSQL</> also provides versions of these functions
2857     that use the regular function invocation syntax
2858     (see <xref linkend="functions-binarystring-other">).
2859    </para>
2860
2861    <table id="functions-binarystring-sql">
2862     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
2863     <tgroup cols="5">
2864      <thead>
2865       <row>
2866        <entry>Function</entry>
2867        <entry>Return Type</entry>
2868        <entry>Description</entry>
2869        <entry>Example</entry>
2870        <entry>Result</entry>
2871       </row>
2872      </thead>
2873
2874      <tbody>
2875       <row>
2876        <entry><literal><parameter>string</parameter> <literal>||</literal>
2877         <parameter>string</parameter></literal></entry>
2878        <entry> <type>bytea</type> </entry>
2879        <entry>
2880         String concatenation
2881         <indexterm>
2882          <primary>binary string</primary>
2883          <secondary>concatenation</secondary>
2884         </indexterm>
2885        </entry>
2886        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
2887        <entry><literal>\\Post'gres\000</literal></entry>
2888       </row>
2889
2890       <row>
2891        <entry>
2892         <indexterm>
2893          <primary>octet_length</primary>
2894         </indexterm>
2895         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
2896        </entry>
2897        <entry><type>int</type></entry>
2898        <entry>Number of bytes in binary string</entry>
2899        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
2900        <entry><literal>5</literal></entry>
2901       </row>
2902
2903       <row>
2904        <entry>
2905         <indexterm>
2906          <primary>overlay</primary>
2907         </indexterm>
2908         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
2909        </entry>
2910        <entry><type>bytea</type></entry>
2911        <entry>
2912         Replace substring
2913        </entry>
2914        <entry><literal>overlay(E'Th\\000omas'::bytea placing E'\\002\\003'::bytea from 2 for 3)</literal></entry>
2915        <entry><literal>T\\002\\003mas</literal></entry>
2916       </row>
2917
2918       <row>
2919        <entry>
2920         <indexterm>
2921          <primary>position</primary>
2922         </indexterm>
2923         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
2924        </entry>
2925        <entry><type>int</type></entry>
2926        <entry>Location of specified substring</entry>
2927       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
2928        <entry><literal>3</literal></entry>
2929       </row>
2930
2931       <row>
2932        <entry>
2933         <indexterm>
2934          <primary>substring</primary>
2935         </indexterm>
2936         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
2937        </entry>
2938        <entry><type>bytea</type></entry>
2939        <entry>
2940         Extract substring
2941        </entry>
2942        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
2943        <entry><literal>h\000o</literal></entry>
2944       </row>
2945
2946       <row>
2947        <entry>
2948         <indexterm>
2949          <primary>trim</primary>
2950         </indexterm>
2951         <literal><function>trim(<optional>both</optional>
2952         <parameter>bytes</parameter> from
2953         <parameter>string</parameter>)</function></literal>
2954        </entry>
2955        <entry><type>bytea</type></entry>
2956        <entry>
2957         Remove the longest string containing only the bytes in
2958         <parameter>bytes</parameter> from the start
2959         and end of <parameter>string</parameter>
2960        </entry>
2961        <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
2962        <entry><literal>Tom</literal></entry>
2963       </row>
2964      </tbody>
2965     </tgroup>
2966    </table>
2967
2968    <para>
2969     Additional binary string manipulation functions are available and
2970     are listed in <xref linkend="functions-binarystring-other">.  Some
2971     of them are used internally to implement the
2972     <acronym>SQL</acronym>-standard string functions listed in <xref
2973     linkend="functions-binarystring-sql">.
2974    </para>
2975
2976    <table id="functions-binarystring-other">
2977     <title>Other Binary String Functions</title>
2978     <tgroup cols="5">
2979      <thead>
2980       <row>
2981        <entry>Function</entry>
2982        <entry>Return Type</entry>
2983        <entry>Description</entry>
2984        <entry>Example</entry>
2985        <entry>Result</entry>
2986       </row>
2987      </thead>
2988
2989      <tbody>
2990       <row>
2991        <entry>
2992         <indexterm>
2993          <primary>btrim</primary>
2994         </indexterm>
2995         <literal><function>btrim(<parameter>string</parameter>
2996         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</function></literal>
2997        </entry>
2998        <entry><type>bytea</type></entry>
2999        <entry>
3000         Remove the longest string consisting only of bytes
3001         in <parameter>bytes</parameter> from the start and end of
3002         <parameter>string</parameter>
3003       </entry>
3004       <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
3005       <entry><literal>trim</literal></entry>
3006      </row>
3007
3008      <row>
3009       <entry>
3010         <indexterm>
3011          <primary>decode</primary>
3012         </indexterm>
3013        <literal><function>decode(<parameter>string</parameter> <type>text</type>,
3014               <parameter>type</parameter> <type>text</type>)</function></literal>
3015       </entry>
3016       <entry><type>bytea</type></entry>
3017       <entry>
3018        Decode binary string from <parameter>string</parameter> previously
3019        encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
3020       </entry>
3021       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
3022       <entry><literal>123\000456</literal></entry>
3023      </row>
3024
3025      <row>
3026       <entry>
3027         <indexterm>
3028          <primary>encode</primary>
3029         </indexterm>
3030        <literal><function>encode(<parameter>string</parameter> <type>bytea</type>,
3031               <parameter>type</parameter> <type>text</type>)</function></literal>
3032       </entry>
3033       <entry><type>text</type></entry>
3034       <entry>
3035        Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
3036        types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
3037       </entry>
3038       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
3039       <entry><literal>123\000456</literal></entry>
3040      </row>
3041
3042       <row>
3043        <entry>
3044         <indexterm>
3045          <primary>get_bit</primary>
3046         </indexterm>
3047         <literal><function>get_bit(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3048        </entry>
3049        <entry><type>int</type></entry>
3050        <entry>
3051         Extract bit from string
3052        </entry>
3053        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
3054        <entry><literal>1</literal></entry>
3055       </row>
3056
3057       <row>
3058        <entry>
3059         <indexterm>
3060          <primary>get_byte</primary>
3061         </indexterm>
3062         <literal><function>get_byte(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3063        </entry>
3064        <entry><type>int</type></entry>
3065        <entry>
3066         Extract byte from string
3067        </entry>
3068        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
3069        <entry><literal>109</literal></entry>
3070       </row>
3071
3072      <row>
3073       <entry>
3074        <indexterm>
3075         <primary>length</primary>
3076        </indexterm>
3077        <literal><function>length(<parameter>string</parameter>)</function></literal>
3078       </entry>
3079       <entry><type>int</type></entry>
3080       <entry>
3081        Length of binary string
3082        <indexterm>
3083         <primary>binary string</primary>
3084         <secondary>length</secondary>
3085        </indexterm>
3086        <indexterm>
3087         <primary>length</primary>
3088         <secondary sortas="binary string">of a binary string</secondary>
3089         <see>binary strings, length</see>
3090        </indexterm>
3091       </entry>
3092       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
3093       <entry><literal>5</literal></entry>
3094      </row>
3095
3096      <row>
3097       <entry>
3098        <indexterm>
3099         <primary>md5</primary>
3100        </indexterm>
3101        <literal><function>md5(<parameter>string</parameter>)</function></literal>
3102       </entry>
3103       <entry><type>text</type></entry>
3104       <entry>
3105        Calculates the MD5 hash of <parameter>string</parameter>,
3106        returning the result in hexadecimal
3107       </entry>
3108       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
3109       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
3110      </row>
3111
3112       <row>
3113        <entry>
3114         <indexterm>
3115          <primary>set_bit</primary>
3116         </indexterm>
3117         <literal><function>set_bit(<parameter>string</parameter>,
3118         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3119        </entry>
3120        <entry><type>bytea</type></entry>
3121        <entry>
3122         Set bit in string
3123        </entry>
3124        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
3125        <entry><literal>Th\000omAs</literal></entry>
3126       </row>
3127
3128       <row>
3129        <entry>
3130         <indexterm>
3131          <primary>set_byte</primary>
3132         </indexterm>
3133         <literal><function>set_byte(<parameter>string</parameter>,
3134         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3135        </entry>
3136        <entry><type>bytea</type></entry>
3137        <entry>
3138         Set byte in string
3139        </entry>
3140        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
3141        <entry><literal>Th\000o@as</literal></entry>
3142       </row>
3143     </tbody>
3144    </tgroup>
3145   </table>
3146
3147   <para>
3148    <function>get_byte</> and <function>set_byte</> number the first byte
3149    of a binary string as byte 0.
3150    <function>get_bit</> and <function>set_bit</> number bits from the
3151    right within each byte; for example bit 0 is the least significant bit of
3152    the first byte, and bit 15 is the most significant bit of the second byte.
3153   </para>
3154  </sect1>
3155
3156
3157   <sect1 id="functions-bitstring">
3158    <title>Bit String Functions and Operators</title>
3159
3160    <indexterm zone="functions-bitstring">
3161     <primary>bit strings</primary>
3162     <secondary>functions</secondary>
3163    </indexterm>
3164
3165    <para>
3166     This section describes functions and operators for examining and
3167     manipulating bit strings, that is values of the types
3168     <type>bit</type> and <type>bit varying</type>.  Aside from the
3169     usual comparison operators, the operators
3170     shown in <xref linkend="functions-bit-string-op-table"> can be used.
3171     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
3172     and <literal>#</literal> must be of equal length.  When bit
3173     shifting, the original length of the string is preserved, as shown
3174     in the examples.
3175    </para>
3176
3177    <table id="functions-bit-string-op-table">
3178     <title>Bit String Operators</title>
3179
3180     <tgroup cols="4">
3181      <thead>
3182       <row>
3183        <entry>Operator</entry>
3184        <entry>Description</entry>
3185        <entry>Example</entry>
3186        <entry>Result</entry>
3187       </row>
3188      </thead>
3189
3190      <tbody>
3191       <row>
3192        <entry> <literal>||</literal> </entry>
3193        <entry>concatenation</entry>
3194        <entry><literal>B'10001' || B'011'</literal></entry>
3195        <entry><literal>10001011</literal></entry>
3196       </row>
3197
3198       <row>
3199        <entry> <literal>&amp;</literal> </entry>
3200        <entry>bitwise AND</entry>
3201        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
3202        <entry><literal>00001</literal></entry>
3203       </row>
3204
3205       <row>
3206        <entry> <literal>|</literal> </entry>
3207        <entry>bitwise OR</entry>
3208        <entry><literal>B'10001' | B'01101'</literal></entry>
3209        <entry><literal>11101</literal></entry>
3210       </row>
3211
3212       <row>
3213        <entry> <literal>#</literal> </entry>
3214        <entry>bitwise XOR</entry>
3215        <entry><literal>B'10001' # B'01101'</literal></entry>
3216        <entry><literal>11100</literal></entry>
3217       </row>
3218
3219       <row>
3220        <entry> <literal>~</literal> </entry>
3221        <entry>bitwise NOT</entry>
3222        <entry><literal>~ B'10001'</literal></entry>
3223        <entry><literal>01110</literal></entry>
3224       </row>
3225
3226       <row>
3227        <entry> <literal>&lt;&lt;</literal> </entry>
3228        <entry>bitwise shift left</entry>
3229        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
3230        <entry><literal>01000</literal></entry>
3231       </row>
3232
3233       <row>
3234        <entry> <literal>&gt;&gt;</literal> </entry>
3235        <entry>bitwise shift right</entry>
3236        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
3237        <entry><literal>00100</literal></entry>
3238       </row>
3239      </tbody>
3240     </tgroup>
3241    </table>
3242
3243    <para>
3244     The following <acronym>SQL</acronym>-standard functions work on bit
3245     strings as well as character strings:
3246     <literal><function>length</function></literal>,
3247     <literal><function>bit_length</function></literal>,
3248     <literal><function>octet_length</function></literal>,
3249     <literal><function>position</function></literal>,
3250     <literal><function>substring</function></literal>,
3251     <literal><function>overlay</function></literal>.
3252    </para>
3253
3254    <para>
3255     The following functions work on bit strings as well as binary
3256     strings:
3257     <literal><function>get_bit</function></literal>,
3258     <literal><function>set_bit</function></literal>.
3259     When working with a bit string, these functions number the first
3260     (leftmost) bit of the string as bit 0.
3261    </para>
3262
3263    <para>
3264     In addition, it is possible to cast integral values to and from type
3265     <type>bit</>.
3266     Some examples:
3267 <programlisting>
3268 44::bit(10)                    <lineannotation>0000101100</lineannotation>
3269 44::bit(3)                     <lineannotation>100</lineannotation>
3270 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
3271 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
3272 </programlisting>
3273     Note that casting to just <quote>bit</> means casting to
3274     <literal>bit(1)</>, and so will deliver only the least significant
3275     bit of the integer.
3276    </para>
3277
3278     <note>
3279      <para>
3280       Prior to <productname>PostgreSQL</productname> 8.0, casting an
3281       integer to <type>bit(n)</> would copy the leftmost <literal>n</>
3282       bits of the integer, whereas now it copies the rightmost <literal>n</>
3283       bits.  Also, casting an integer to a bit string width wider than
3284       the integer itself will sign-extend on the left.
3285      </para>
3286     </note>
3287
3288   </sect1>
3289
3290
3291  <sect1 id="functions-matching">
3292   <title>Pattern Matching</title>
3293
3294   <indexterm zone="functions-matching">
3295    <primary>pattern matching</primary>
3296   </indexterm>
3297
3298    <para>
3299     There are three separate approaches to pattern matching provided
3300     by <productname>PostgreSQL</productname>: the traditional
3301     <acronym>SQL</acronym> <function>LIKE</function> operator, the
3302     more recent <function>SIMILAR TO</function> operator (added in
3303     SQL:1999), and <acronym>POSIX</acronym>-style regular
3304     expressions.  Aside from the basic <quote>does this string match
3305     this pattern?</> operators, functions are available to extract
3306     or replace matching substrings and to split a string at matching
3307     locations.
3308    </para>
3309
3310    <tip>
3311     <para>
3312      If you have pattern matching needs that go beyond this,
3313      consider writing a user-defined function in Perl or Tcl.
3314     </para>
3315    </tip>
3316
3317   <sect2 id="functions-like">
3318    <title><function>LIKE</function></title>
3319
3320    <indexterm>
3321     <primary>LIKE</primary>
3322    </indexterm>
3323
3324 <synopsis>
3325 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3326 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3327 </synopsis>
3328
3329     <para>
3330      The <function>LIKE</function> expression returns true if the
3331      <replaceable>string</replaceable> matches the supplied
3332      <replaceable>pattern</replaceable>.  (As
3333      expected, the <function>NOT LIKE</function> expression returns
3334      false if <function>LIKE</function> returns true, and vice versa.
3335      An equivalent expression is
3336      <literal>NOT (<replaceable>string</replaceable> LIKE
3337       <replaceable>pattern</replaceable>)</literal>.)
3338     </para>
3339
3340     <para>
3341      If <replaceable>pattern</replaceable> does not contain percent
3342      signs or underscores, then the pattern only represents the string
3343      itself; in that case <function>LIKE</function> acts like the
3344      equals operator.  An underscore (<literal>_</literal>) in
3345      <replaceable>pattern</replaceable> stands for (matches) any single
3346      character; a percent sign (<literal>%</literal>) matches any sequence
3347      of zero or more characters.
3348     </para>
3349
3350    <para>
3351     Some examples:
3352 <programlisting>
3353 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
3354 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
3355 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
3356 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
3357 </programlisting>
3358    </para>
3359
3360    <para>
3361     <function>LIKE</function> pattern matching always covers the entire
3362     string.  Therefore, to match a sequence anywhere within a string, the
3363     pattern must start and end with a percent sign.
3364    </para>
3365
3366    <para>
3367     To match a literal underscore or percent sign without matching
3368     other characters, the respective character in
3369     <replaceable>pattern</replaceable> must be
3370     preceded by the escape character.  The default escape
3371     character is the backslash but a different one can be selected by
3372     using the <literal>ESCAPE</literal> clause.  To match the escape
3373     character itself, write two escape characters.
3374    </para>
3375
3376    <para>
3377     Note that the backslash already has a special meaning in string literals,
3378     so to write a pattern constant that contains a backslash you must write two
3379     backslashes in an SQL statement (assuming escape string syntax is used, see
3380     <xref linkend="sql-syntax-strings">).  Thus, writing a pattern that
3381     actually matches a literal backslash means writing four backslashes in the
3382     statement.  You can avoid this by selecting a different escape character
3383     with <literal>ESCAPE</literal>; then a backslash is not special to
3384     <function>LIKE</function> anymore. (But backslash is still special to the
3385     string literal parser, so you still need two of them to match a backslash.)
3386    </para>
3387
3388    <para>
3389     It's also possible to select no escape character by writing
3390     <literal>ESCAPE ''</literal>.  This effectively disables the
3391     escape mechanism, which makes it impossible to turn off the
3392     special meaning of underscore and percent signs in the pattern.
3393    </para>
3394
3395    <para>
3396     The key word <token>ILIKE</token> can be used instead of
3397     <token>LIKE</token> to make the match case-insensitive according
3398     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3399     <productname>PostgreSQL</productname> extension.
3400    </para>
3401
3402    <para>
3403     The operator <literal>~~</literal> is equivalent to
3404     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3405     <function>ILIKE</function>.  There are also
3406     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3407     represent <function>NOT LIKE</function> and <function>NOT
3408     ILIKE</function>, respectively.  All of these operators are
3409     <productname>PostgreSQL</productname>-specific.
3410    </para>
3411   </sect2>
3412
3413
3414   <sect2 id="functions-similarto-regexp">
3415    <title><function>SIMILAR TO</function> Regular Expressions</title>
3416
3417    <indexterm>
3418     <primary>regular expression</primary>
3419     <!-- <seealso>pattern matching</seealso> breaks index build -->
3420    </indexterm>
3421
3422    <indexterm>
3423     <primary>SIMILAR TO</primary>
3424    </indexterm>
3425    <indexterm>
3426     <primary>substring</primary>
3427    </indexterm>
3428
3429 <synopsis>
3430 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3431 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3432 </synopsis>
3433
3434    <para>
3435     The <function>SIMILAR TO</function> operator returns true or
3436     false depending on whether its pattern matches the given string.
3437     It is similar to <function>LIKE</function>, except that it
3438     interprets the pattern using the SQL standard's definition of a
3439     regular expression.  SQL regular expressions are a curious cross
3440     between <function>LIKE</function> notation and common regular
3441     expression notation.
3442    </para>
3443
3444    <para>
3445     Like <function>LIKE</function>, the <function>SIMILAR TO</function>
3446     operator succeeds only if its pattern matches the entire string;
3447     this is unlike common regular expression behavior where the pattern
3448     can match any part of the string.
3449     Also like
3450     <function>LIKE</function>, <function>SIMILAR TO</function> uses
3451     <literal>_</> and <literal>%</> as wildcard characters denoting
3452     any single character and any string, respectively (these are
3453     comparable to <literal>.</> and <literal>.*</> in POSIX regular
3454     expressions).
3455    </para>
3456
3457    <para>
3458     In addition to these facilities borrowed from <function>LIKE</function>,
3459     <function>SIMILAR TO</function> supports these pattern-matching
3460     metacharacters borrowed from POSIX regular expressions:
3461
3462    <itemizedlist>
3463     <listitem>
3464      <para>
3465       <literal>|</literal> denotes alternation (either of two alternatives).
3466      </para>
3467     </listitem>
3468     <listitem>
3469      <para>
3470       <literal>*</literal> denotes repetition of the previous item zero
3471       or more times.
3472      </para>
3473     </listitem>
3474     <listitem>
3475      <para>
3476       <literal>+</literal> denotes repetition of the previous item one
3477       or more times.
3478      </para>
3479     </listitem>
3480     <listitem>
3481      <para>
3482       <literal>?</literal> denotes repetition of the previous item zero
3483       or one time.
3484      </para>
3485     </listitem>
3486     <listitem>
3487      <para>
3488       <literal>{</><replaceable>m</><literal>}</literal> denotes repetition
3489       of the previous item exactly <replaceable>m</> times.
3490      </para>
3491     </listitem>
3492     <listitem>
3493      <para>
3494       <literal>{</><replaceable>m</><literal>,}</literal> denotes repetition
3495       of the previous item <replaceable>m</> or more times.
3496      </para>
3497     </listitem>
3498     <listitem>
3499      <para>
3500       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
3501       denotes repetition of the previous item at least <replaceable>m</> and
3502       not more than <replaceable>n</> times.
3503      </para>
3504     </listitem>
3505     <listitem>
3506      <para>
3507       Parentheses <literal>()</literal> can be used to group items into
3508       a single logical item.
3509      </para>
3510     </listitem>
3511     <listitem>
3512      <para>
3513       A bracket expression <literal>[...]</literal> specifies a character
3514       class, just as in POSIX regular expressions.
3515      </para>
3516     </listitem>
3517    </itemizedlist>
3518
3519     Notice that the period (<literal>.</>) is not a metacharacter
3520     for <function>SIMILAR TO</>.
3521    </para>
3522
3523    <para>
3524     As with <function>LIKE</>, a backslash disables the special meaning
3525     of any of these metacharacters; or a different escape character can
3526     be specified with <literal>ESCAPE</>.
3527    </para>
3528
3529    <para>
3530     Some examples:
3531 <programlisting>
3532 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
3533 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
3534 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
3535 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
3536 </programlisting>
3537    </para>
3538
3539    <para>
3540     The <function>substring</> function with three parameters,
3541     <function>substring(<replaceable>string</replaceable> from
3542     <replaceable>pattern</replaceable> for
3543     <replaceable>escape-character</replaceable>)</function>, provides
3544     extraction of a substring that matches an SQL
3545     regular expression pattern.  As with <literal>SIMILAR TO</>, the
3546     specified pattern must match the entire data string, or else the
3547     function fails and returns null.  To indicate the part of the
3548     pattern that should be returned on success, the pattern must contain
3549     two occurrences of the escape character followed by a double quote
3550     (<literal>"</>). <!-- " font-lock sanity -->
3551     The text matching the portion of the pattern
3552     between these markers is returned.
3553    </para>
3554
3555    <para>
3556     Some examples, with <literal>#&quot;</> delimiting the return string:
3557 <programlisting>
3558 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
3559 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
3560 </programlisting>
3561    </para>
3562   </sect2>
3563
3564   <sect2 id="functions-posix-regexp">
3565    <title><acronym>POSIX</acronym> Regular Expressions</title>
3566
3567    <indexterm zone="functions-posix-regexp">
3568     <primary>regular expression</primary>
3569     <seealso>pattern matching</seealso>
3570    </indexterm>
3571    <indexterm>
3572     <primary>substring</primary>
3573    </indexterm>
3574    <indexterm>
3575     <primary>regexp_replace</primary>
3576    </indexterm>
3577    <indexterm>
3578     <primary>regexp_matches</primary>
3579    </indexterm>
3580    <indexterm>
3581     <primary>regexp_split_to_table</primary>
3582    </indexterm>
3583    <indexterm>
3584     <primary>regexp_split_to_array</primary>
3585    </indexterm>
3586
3587    <para>
3588     <xref linkend="functions-posix-table"> lists the available
3589     operators for pattern matching using POSIX regular expressions.
3590    </para>
3591
3592    <table id="functions-posix-table">
3593     <title>Regular Expression Match Operators</title>
3594
3595     <tgroup cols="3">
3596      <thead>
3597       <row>
3598        <entry>Operator</entry>
3599        <entry>Description</entry>
3600        <entry>Example</entry>
3601       </row>
3602      </thead>
3603
3604       <tbody>
3605        <row>
3606         <entry> <literal>~</literal> </entry>
3607         <entry>Matches regular expression, case sensitive</entry>
3608         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3609        </row>
3610
3611        <row>
3612         <entry> <literal>~*</literal> </entry>
3613         <entry>Matches regular expression, case insensitive</entry>
3614         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3615        </row>
3616
3617        <row>
3618         <entry> <literal>!~</literal> </entry>
3619         <entry>Does not match regular expression, case sensitive</entry>
3620         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3621        </row>
3622
3623        <row>
3624         <entry> <literal>!~*</literal> </entry>
3625         <entry>Does not match regular expression, case insensitive</entry>
3626         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3627        </row>
3628       </tbody>
3629      </tgroup>
3630     </table>
3631
3632     <para>
3633      <acronym>POSIX</acronym> regular expressions provide a more
3634      powerful means for pattern matching than the <function>LIKE</function> and
3635      <function>SIMILAR TO</> operators.
3636      Many Unix tools such as <command>egrep</command>,
3637      <command>sed</command>, or <command>awk</command> use a pattern
3638      matching language that is similar to the one described here.
3639     </para>
3640
3641     <para>
3642      A regular expression is a character sequence that is an
3643      abbreviated definition of a set of strings (a <firstterm>regular
3644      set</firstterm>).  A string is said to match a regular expression
3645      if it is a member of the regular set described by the regular
3646      expression.  As with <function>LIKE</function>, pattern characters
3647      match string characters exactly unless they are special characters
3648      in the regular expression language &mdash; but regular expressions use
3649      different special characters than <function>LIKE</function> does.
3650      Unlike <function>LIKE</function> patterns, a
3651      regular expression is allowed to match anywhere within a string, unless
3652      the regular expression is explicitly anchored to the beginning or
3653      end of the string.
3654     </para>
3655
3656     <para>
3657      Some examples:
3658 <programlisting>
3659 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
3660 'abc' ~ '^a'     <lineannotation>true</lineannotation>
3661 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
3662 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3663 </programlisting>
3664     </para>
3665
3666     <para>
3667      The <acronym>POSIX</acronym> pattern language is described in much
3668      greater detail below.
3669     </para>
3670
3671     <para>
3672      The <function>substring</> function with two parameters,
3673      <function>substring(<replaceable>string</replaceable> from
3674      <replaceable>pattern</replaceable>)</function>, provides extraction of a
3675      substring
3676      that matches a POSIX regular expression pattern.  It returns null if
3677      there is no match, otherwise the portion of the text that matched the
3678      pattern.  But if the pattern contains any parentheses, the portion
3679      of the text that matched the first parenthesized subexpression (the
3680      one whose left parenthesis comes first) is
3681      returned.  You can put parentheses around the whole expression
3682      if you want to use parentheses within it without triggering this
3683      exception.  If you need parentheses in the pattern before the
3684      subexpression you want to extract, see the non-capturing parentheses
3685      described below.
3686     </para>
3687
3688    <para>
3689     Some examples:
3690 <programlisting>
3691 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
3692 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
3693 </programlisting>
3694    </para>
3695
3696     <para>
3697      The <function>regexp_replace</> function provides substitution of
3698      new text for substrings that match POSIX regular expression patterns.
3699      It has the syntax
3700      <function>regexp_replace</function>(<replaceable>source</>,
3701      <replaceable>pattern</>, <replaceable>replacement</>
3702      <optional>, <replaceable>flags</> </optional>).
3703      The <replaceable>source</> string is returned unchanged if
3704      there is no match to the <replaceable>pattern</>.  If there is a
3705      match, the <replaceable>source</> string is returned with the
3706      <replaceable>replacement</> string substituted for the matching
3707      substring.  The <replaceable>replacement</> string can contain
3708      <literal>\</><replaceable>n</>, where <replaceable>n</> is 1
3709      through 9, to indicate that the source substring matching the
3710      <replaceable>n</>'th parenthesized subexpression of the pattern should be
3711      inserted, and it can contain <literal>\&amp;</> to indicate that the
3712      substring matching the entire pattern should be inserted.  Write
3713      <literal>\\</> if you need to put a literal backslash in the replacement
3714      text.  (As always, remember to double backslashes written in literal
3715      constant strings, assuming escape string syntax is used.)
3716      The <replaceable>flags</> parameter is an optional text
3717      string containing zero or more single-letter flags that change the
3718      function's behavior.  Flag <literal>i</> specifies case-insensitive
3719      matching, while flag <literal>g</> specifies replacement of each matching
3720      substring rather than only the first one.  Other supported flags are
3721      described in <xref linkend="posix-embedded-options-table">.
3722     </para>
3723
3724    <para>
3725     Some examples:
3726 <programlisting>
3727 regexp_replace('foobarbaz', 'b..', 'X')
3728                                    <lineannotation>fooXbaz</lineannotation>
3729 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3730                                    <lineannotation>fooXX</lineannotation>
3731 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3732                                    <lineannotation>fooXarYXazY</lineannotation>
3733 </programlisting>
3734    </para>
3735
3736     <para>
3737      The <function>regexp_matches</> function returns a text array of
3738      all of the captured substrings resulting from matching a POSIX
3739      regular expression pattern.  It has the syntax
3740      <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3741      <optional>, <replaceable>flags</> </optional>).
3742      The function can return no rows, one row, or multiple rows (see
3743      the <literal>g</> flag below).  If the <replaceable>pattern</>
3744      does not match, the function returns no rows.  If the pattern
3745      contains no parenthesized subexpressions, then each row
3746      returned is a single-element text array containing the substring
3747      matching the whole pattern.  If the pattern contains parenthesized
3748      subexpressions, the function returns a text array whose
3749      <replaceable>n</>'th element is the substring matching the
3750      <replaceable>n</>'th parenthesized subexpression of the pattern
3751      (not counting <quote>non-capturing</> parentheses; see below for
3752      details).
3753      The <replaceable>flags</> parameter is an optional text
3754      string containing zero or more single-letter flags that change the
3755      function's behavior.  Flag <literal>g</> causes the function to find
3756      each match in the string, not only the first one, and return a row for
3757      each such match.  Other supported
3758      flags are described in <xref linkend="posix-embedded-options-table">.
3759     </para>
3760
3761    <para>
3762     Some examples:
3763 <programlisting>
3764 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3765  regexp_matches 
3766 ----------------
3767  {bar,beque}
3768 (1 row)
3769
3770 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3771  regexp_matches 
3772 ----------------
3773  {bar,beque}
3774  {bazil,barf}
3775 (2 rows)
3776
3777 SELECT regexp_matches('foobarbequebaz', 'barbeque');
3778  regexp_matches 
3779 ----------------
3780  {barbeque}
3781 (1 row)
3782 </programlisting>
3783    </para>
3784
3785    <para>
3786     It is possible to force <function>regexp_matches()</> to always
3787     return one row by using a sub-select;  this is particularly useful
3788     in a <literal>SELECT</> target list when you want all rows
3789     returned, even non-matching ones:
3790 <programlisting>
3791 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
3792 </programlisting>
3793    </para>
3794
3795     <para>
3796      The <function>regexp_split_to_table</> function splits a string using a POSIX
3797      regular expression pattern as a delimiter.  It has the syntax
3798      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
3799      <optional>, <replaceable>flags</> </optional>).
3800      If there is no match to the <replaceable>pattern</>, the function returns the
3801      <replaceable>string</>.  If there is at least one match, for each match it returns
3802      the text from the end of the last match (or the beginning of the string)
3803      to the beginning of the match.  When there are no more matches, it
3804      returns the text from the end of the last match to the end of the string.
3805      The <replaceable>flags</> parameter is an optional text string containing
3806      zero or more single-letter flags that change the function's behavior.
3807      <function>regexp_split_to_table</function> supports the flags described in
3808      <xref linkend="posix-embedded-options-table">.
3809     </para>
3810
3811     <para>
3812      The <function>regexp_split_to_array</> function behaves the same as
3813      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
3814      returns its result as an array of <type>text</>.  It has the syntax
3815      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
3816      <optional>, <replaceable>flags</> </optional>).
3817      The parameters are the same as for <function>regexp_split_to_table</>.
3818     </para>
3819
3820    <para>
3821     Some examples:
3822 <programlisting>
3823
3824 SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\s+') AS foo;
3825   foo   
3826 --------
3827  the    
3828  quick  
3829  brown  
3830  fox    
3831  jumped 
3832  over   
3833  the    
3834  lazy   
3835  dog    
3836 (9 rows)
3837
3838 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
3839               regexp_split_to_array             
3840 ------------------------------------------------
3841  {the,quick,brown,fox,jumped,over,the,lazy,dog}
3842 (1 row)
3843
3844 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
3845  foo 
3846 -----
3847  t         
3848  h         
3849  e         
3850  q         
3851  u         
3852  i         
3853  c         
3854  k         
3855  b         
3856  r         
3857  o         
3858  w         
3859  n         
3860  f         
3861  o         
3862  x         
3863 (16 rows)
3864 </programlisting>
3865    </para>
3866
3867    <para>
3868     As the last example demonstrates, the regexp split functions ignore
3869     zero-length matches that occur at the start or end of the string
3870     or immediately after a previous match.  This is contrary to the strict
3871     definition of regexp matching that is implemented by
3872     <function>regexp_matches</>, but is usually the most convenient behavior
3873     in practice.  Other software systems such as Perl use similar definitions.
3874    </para>
3875
3876 <!-- derived from the re_syntax.n man page -->
3877
3878    <sect3 id="posix-syntax-details">
3879     <title>Regular Expression Details</title>
3880
3881    <para>
3882     <productname>PostgreSQL</productname>'s regular expressions are implemented
3883     using a software package written by Henry Spencer.  Much of
3884     the description of regular expressions below is copied verbatim from his
3885     manual.
3886    </para>
3887
3888    <para>
3889     Regular expressions (<acronym>RE</acronym>s), as defined in
3890     <acronym>POSIX</acronym> 1003.2, come in two forms:
3891     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
3892     (roughly those of <command>egrep</command>), and
3893     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
3894     (roughly those of <command>ed</command>).
3895     <productname>PostgreSQL</productname> supports both forms, and
3896     also implements some extensions
3897     that are not in the POSIX standard, but have become widely used
3898     due to their availability in programming languages such as Perl and Tcl.
3899     <acronym>RE</acronym>s using these non-POSIX extensions are called
3900     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
3901     in this documentation.  AREs are almost an exact superset of EREs,
3902     but BREs have several notational incompatibilities (as well as being
3903     much more limited).
3904     We first describe the ARE and ERE forms, noting features that apply
3905     only to AREs, and then describe how BREs differ.
3906    </para>
3907
3908    <note>
3909     <para>
3910      <productname>PostgreSQL</> always initially presumes that a regular
3911      expression follows the ARE rules.  However, the more limited ERE or
3912      BRE rules can be chosen by prepending an <firstterm>embedded option</>
3913      to the RE pattern, as described in <xref linkend="posix-metasyntax">.
3914      This can be useful for compatibility with applications that expect
3915      exactly the <acronym>POSIX</acronym> 1003.2 rules.
3916     </para>
3917    </note>
3918
3919    <para>
3920     A regular expression is defined as one or more
3921     <firstterm>branches</firstterm>, separated by
3922     <literal>|</literal>.  It matches anything that matches one of the
3923     branches.
3924    </para>
3925
3926    <para>
3927     A branch is zero or more <firstterm>quantified atoms</> or
3928     <firstterm>constraints</>, concatenated.
3929     It matches a match for the first, followed by a match for the second, etc;
3930     an empty branch matches the empty string.
3931    </para>
3932
3933    <para>
3934     A quantified atom is an <firstterm>atom</> possibly followed
3935     by a single <firstterm>quantifier</>.
3936     Without a quantifier, it matches a match for the atom.
3937     With a quantifier, it can match some number of matches of the atom.
3938     An <firstterm>atom</firstterm> can be any of the possibilities
3939     shown in <xref linkend="posix-atoms-table">.
3940     The possible quantifiers and their meanings are shown in
3941     <xref linkend="posix-quantifiers-table">.
3942    </para>
3943
3944    <para>
3945     A <firstterm>constraint</> matches an empty string, but matches only when
3946     specific conditions are met.  A constraint can be used where an atom
3947     could be used, except it cannot be followed by a quantifier.
3948     The simple constraints are shown in
3949     <xref linkend="posix-constraints-table">;
3950     some more constraints are described later.
3951    </para>
3952
3953
3954    <table id="posix-atoms-table">
3955     <title>Regular Expression Atoms</title>
3956
3957     <tgroup cols="2">
3958      <thead>
3959       <row>
3960        <entry>Atom</entry>
3961        <entry>Description</entry>
3962       </row>
3963      </thead>
3964
3965       <tbody>
3966        <row>
3967        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3968        <entry> (where <replaceable>re</> is any regular expression)
3969        matches a match for
3970        <replaceable>re</>, with the match noted for possible reporting </entry>
3971        </row>
3972
3973        <row>
3974        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3975        <entry> as above, but the match is not noted for reporting
3976        (a <quote>non-capturing</> set of parentheses)
3977        (AREs only) </entry>
3978        </row>
3979
3980        <row>
3981        <entry> <literal>.</> </entry>
3982        <entry> matches any single character </entry>
3983        </row>
3984
3985        <row>
3986        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
3987        <entry> a <firstterm>bracket expression</>,
3988        matching any one of the <replaceable>chars</> (see
3989        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
3990        </row>
3991
3992        <row>
3993        <entry> <literal>\</><replaceable>k</> </entry>
3994        <entry> (where <replaceable>k</> is a non-alphanumeric character)
3995        matches that character taken as an ordinary character,
3996        e.g., <literal>\\</> matches a backslash character </entry>
3997        </row>
3998
3999        <row>
4000        <entry> <literal>\</><replaceable>c</> </entry>
4001        <entry> where <replaceable>c</> is alphanumeric
4002        (possibly followed by other characters)
4003        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
4004        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
4005        </row>
4006
4007        <row>
4008        <entry> <literal>{</> </entry>
4009        <entry> when followed by a character other than a digit,
4010        matches the left-brace character <literal>{</>;
4011        when followed by a digit, it is the beginning of a
4012        <replaceable>bound</> (see below) </entry>
4013        </row>
4014
4015        <row>
4016        <entry> <replaceable>x</> </entry>
4017        <entry> where <replaceable>x</> is a single character with no other
4018        significance, matches that character </entry>
4019        </row>
4020       </tbody>
4021      </tgroup>
4022     </table>
4023
4024    <para>
4025     An RE cannot end with <literal>\</>.
4026    </para>
4027
4028    <note>
4029     <para>
4030      Remember that the backslash (<literal>\</literal>) already has a special
4031      meaning in <productname>PostgreSQL</> string literals.
4032      To write a pattern constant that contains a backslash,
4033      you must write two backslashes in the statement, assuming escape
4034      string syntax is used (see <xref linkend="sql-syntax-strings">).
4035     </para>
4036    </note>
4037
4038    <table id="posix-quantifiers-table">
4039     <title>Regular Expression Quantifiers</title>
4040
4041     <tgroup cols="2">
4042      <thead>
4043       <row>
4044        <entry>Quantifier</entry>
4045        <entry>Matches</entry>
4046       </row>
4047      </thead>
4048
4049       <tbody>
4050        <row>
4051        <entry> <literal>*</> </entry>
4052        <entry> a sequence of 0 or more matches of the atom </entry>
4053        </row>
4054
4055        <row>
4056        <entry> <literal>+</> </entry>
4057        <entry> a sequence of 1 or more matches of the atom </entry>
4058        </row>
4059
4060        <row>
4061        <entry> <literal>?</> </entry>
4062        <entry> a sequence of 0 or 1 matches of the atom </entry>
4063        </row>
4064
4065        <row>
4066        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
4067        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
4068        </row>
4069
4070        <row>
4071        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
4072        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
4073        </row>
4074
4075        <row>
4076        <entry>
4077        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4078        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
4079        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
4080        <replaceable>n</> </entry>
4081        </row>
4082
4083        <row>
4084        <entry> <literal>*?</> </entry>
4085        <entry> non-greedy version of <literal>*</> </entry>
4086        </row>
4087
4088        <row>
4089        <entry> <literal>+?</> </entry>
4090        <entry> non-greedy version of <literal>+</> </entry>
4091        </row>
4092
4093        <row>
4094        <entry> <literal>??</> </entry>
4095        <entry> non-greedy version of <literal>?</> </entry>
4096        </row>
4097
4098        <row>
4099        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
4100        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
4101        </row>
4102
4103        <row>
4104        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
4105        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
4106        </row>
4107
4108        <row>
4109        <entry>
4110        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
4111        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4112        </row>
4113       </tbody>
4114      </tgroup>
4115     </table>
4116
4117    <para>
4118     The forms using <literal>{</><replaceable>...</><literal>}</>
4119     are known as <firstterm>bounds</>.
4120     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
4121     unsigned decimal integers with permissible values from 0 to 255 inclusive.
4122    </para>
4123
4124     <para>
4125      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
4126      same possibilities as their corresponding normal (<firstterm>greedy</>)
4127      counterparts, but prefer the smallest number rather than the largest
4128      number of matches.
4129      See <xref linkend="posix-matching-rules"> for more detail.
4130    </para>
4131
4132    <note>
4133     <para>
4134      A quantifier cannot immediately follow another quantifier, e.g.,
4135      <literal>**</> is invalid.
4136      A quantifier cannot
4137      begin an expression or subexpression or follow
4138      <literal>^</literal> or <literal>|</literal>.
4139     </para>
4140    </note>
4141
4142    <table id="posix-constraints-table">
4143     <title>Regular Expression Constraints</title>
4144
4145     <tgroup cols="2">
4146      <thead>
4147       <row>
4148        <entry>Constraint</entry>
4149        <entry>Description</entry>
4150       </row>
4151      </thead>
4152
4153       <tbody>
4154        <row>
4155        <entry> <literal>^</> </entry>
4156        <entry> matches at the beginning of the string </entry>
4157        </row>
4158
4159        <row>
4160        <entry> <literal>$</> </entry>
4161        <entry> matches at the end of the string </entry>
4162        </row>
4163
4164        <row>
4165        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
4166        <entry> <firstterm>positive lookahead</> matches at any point
4167        where a substring matching <replaceable>re</> begins
4168        (AREs only) </entry>
4169        </row>
4170
4171        <row>
4172        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
4173        <entry> <firstterm>negative lookahead</> matches at any point
4174        where no substring matching <replaceable>re</> begins
4175        (AREs only) </entry>
4176        </row>
4177       </tbody>
4178      </tgroup>
4179     </table>
4180
4181    <para>
4182     Lookahead constraints cannot contain <firstterm>back references</>
4183     (see <xref linkend="posix-escape-sequences">),
4184     and all parentheses within them are considered non-capturing.
4185    </para>
4186    </sect3>
4187
4188    <sect3 id="posix-bracket-expressions">
4189     <title>Bracket Expressions</title>
4190
4191    <para>
4192     A <firstterm>bracket expression</firstterm> is a list of
4193     characters enclosed in <literal>[]</literal>.  It normally matches
4194     any single character from the list (but see below).  If the list
4195     begins with <literal>^</literal>, it matches any single character
4196     <emphasis>not</> from the rest of the list.
4197     If two characters
4198     in the list are separated by <literal>-</literal>, this is
4199     shorthand for the full range of characters between those two
4200     (inclusive) in the collating sequence,
4201     e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
4202     any decimal digit.  It is illegal for two ranges to share an
4203     endpoint, e.g.,  <literal>a-c-e</literal>.  Ranges are very
4204     collating-sequence-dependent, so portable programs should avoid
4205     relying on them.
4206    </para>
4207
4208    <para>
4209     To include a literal <literal>]</literal> in the list, make it the
4210     first character (after <literal>^</literal>, if that is used).  To
4211     include a literal <literal>-</literal>, make it the first or last
4212     character, or the second endpoint of a range.  To use a literal
4213     <literal>-</literal> as the first endpoint of a range, enclose it
4214     in <literal>[.</literal> and <literal>.]</literal> to make it a
4215     collating element (see below).  With the exception of these characters,
4216     some combinations using <literal>[</literal>
4217     (see next paragraphs), and escapes (AREs only), all other special
4218     characters lose their special significance within a bracket expression.
4219     In particular, <literal>\</literal> is not special when following
4220     ERE or BRE rules, though it is special (as introducing an escape)
4221     in AREs.
4222    </para>
4223
4224    <para>
4225     Within a bracket expression, a collating element (a character, a
4226     multiple-character sequence that collates as if it were a single
4227     character, or a collating-sequence name for either) enclosed in
4228     <literal>[.</literal> and <literal>.]</literal> stands for the
4229     sequence of characters of that collating element.  The sequence is
4230     treated as a single element of the bracket expression's list.  This
4231     allows a bracket
4232     expression containing a multiple-character collating element to
4233     match more than one character, e.g., if the collating sequence
4234     includes a <literal>ch</literal> collating element, then the RE
4235     <literal>[[.ch.]]*c</literal> matches the first five characters of
4236     <literal>chchcc</literal>.
4237    </para>
4238
4239    <note>
4240     <para>
4241      <productname>PostgreSQL</> currently does not support multi-character collating
4242      elements. This information describes possible future behavior.
4243     </para>
4244    </note>
4245
4246    <para>
4247     Within a bracket expression, a collating element enclosed in
4248     <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
4249     class</>, standing for the sequences of characters of all collating
4250     elements equivalent to that one, including itself.  (If there are
4251     no other equivalent collating elements, the treatment is as if the
4252     enclosing delimiters were <literal>[.</literal> and
4253     <literal>.]</literal>.)  For example, if <literal>o</literal> and
4254     <literal>^</literal> are the members of an equivalence class, then
4255     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
4256     <literal>[o^]</literal> are all synonymous.  An equivalence class
4257     cannot be an endpoint of a range.
4258    </para>
4259
4260    <para>
4261     Within a bracket expression, the name of a character class
4262     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
4263     for the list of all characters belonging to that class.  Standard
4264     character class names are: <literal>alnum</literal>,
4265     <literal>alpha</literal>, <literal>blank</literal>,
4266     <literal>cntrl</literal>, <literal>digit</literal>,
4267     <literal>graph</literal>, <literal>lower</literal>,
4268     <literal>print</literal>, <literal>punct</literal>,
4269     <literal>space</literal>, <literal>upper</literal>,
4270     <literal>xdigit</literal>.  These stand for the character classes
4271     defined in
4272     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
4273     A locale can provide others.  A character class cannot be used as
4274     an endpoint of a range.
4275    </para>
4276
4277    <para>
4278     There are two special cases of bracket expressions:  the bracket
4279     expressions <literal>[[:&lt;:]]</literal> and
4280     <literal>[[:&gt;:]]</literal> are constraints,
4281     matching empty strings at the beginning
4282     and end of a word respectively.  A word is defined as a sequence
4283     of word characters that is neither preceded nor followed by word
4284     characters.  A word character is an <literal>alnum</> character (as
4285     defined by
4286     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
4287     or an underscore.  This is an extension, compatible with but not
4288     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
4289     caution in software intended to be portable to other systems.
4290     The constraint escapes described below are usually preferable; they
4291     are no more standard, but are easier to type.
4292    </para>
4293    </sect3>
4294
4295    <sect3 id="posix-escape-sequences">
4296     <title>Regular Expression Escapes</title>
4297
4298    <para>
4299     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
4300     followed by an alphanumeric character. Escapes come in several varieties:
4301     character entry, class shorthands, constraint escapes, and back references.
4302     A <literal>\</> followed by an alphanumeric character but not constituting
4303     a valid escape is illegal in AREs.
4304     In EREs, there are no escapes: outside a bracket expression,
4305     a <literal>\</> followed by an alphanumeric character merely stands for
4306     that character as an ordinary character, and inside a bracket expression,
4307     <literal>\</> is an ordinary character.
4308     (The latter is the one actual incompatibility between EREs and AREs.)
4309    </para>
4310
4311    <para>
4312     <firstterm>Character-entry escapes</> exist to make it easier to specify
4313     non-printing and other inconvenient characters in REs.  They are
4314     shown in <xref linkend="posix-character-entry-escapes-table">.
4315    </para>
4316
4317    <para>
4318     <firstterm>Class-shorthand escapes</> provide shorthands for certain
4319     commonly-used character classes.  They are
4320     shown in <xref linkend="posix-class-shorthand-escapes-table">.
4321    </para>
4322
4323    <para>
4324     A <firstterm>constraint escape</> is a constraint,
4325     matching the empty string if specific conditions are met,
4326     written as an escape.  They are
4327     shown in <xref linkend="posix-constraint-escapes-table">.
4328    </para>
4329
4330    <para>
4331     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
4332     same string matched by the previous parenthesized subexpression specified
4333     by the number <replaceable>n</>
4334     (see <xref linkend="posix-constraint-backref-table">).  For example,
4335     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
4336     but not <literal>bc</> or <literal>cb</>.
4337     The subexpression must entirely precede the back reference in the RE.
4338     Subexpressions are numbered in the order of their leading parentheses.
4339     Non-capturing parentheses do not define subexpressions.
4340    </para>
4341
4342    <note>
4343     <para>
4344      Keep in mind that an escape's leading <literal>\</> will need to be
4345      doubled when entering the pattern as an SQL string constant.  For example:
4346 <programlisting>
4347 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
4348 </programlisting>
4349     </para>
4350    </note>
4351
4352    <table id="posix-character-entry-escapes-table">
4353     <title>Regular Expression Character-entry Escapes</title>
4354
4355     <tgroup cols="2">
4356      <thead>
4357       <row>
4358        <entry>Escape</entry>
4359        <entry>Description</entry>
4360       </row>
4361      </thead>
4362
4363       <tbody>
4364        <row>
4365        <entry> <literal>\a</> </entry>
4366        <entry> alert (bell) character, as in C </entry>
4367        </row>
4368
4369        <row>
4370        <entry> <literal>\b</> </entry>
4371        <entry> backspace, as in C </entry>
4372        </row>
4373
4374        <row>
4375        <entry> <literal>\B</> </entry>
4376        <entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
4377        doubling </entry>
4378        </row>
4379
4380        <row>
4381        <entry> <literal>\c</><replaceable>X</> </entry>
4382        <entry> (where <replaceable>X</> is any character) the character whose
4383        low-order 5 bits are the same as those of
4384        <replaceable>X</>, and whose other bits are all zero </entry>
4385        </row>
4386
4387        <row>
4388        <entry> <literal>\e</> </entry>
4389        <entry> the character whose collating-sequence name
4390        is <literal>ESC</>,
4391        or failing that, the character with octal value 033 </entry>
4392        </row>
4393
4394        <row>
4395        <entry> <literal>\f</> </entry>
4396        <entry> form feed, as in C </entry>
4397        </row>
4398
4399        <row>
4400        <entry> <literal>\n</> </entry>
4401        <entry> newline, as in C </entry>
4402        </row>
4403
4404        <row>
4405        <entry> <literal>\r</> </entry>
4406        <entry> carriage return, as in C </entry>
4407        </row>
4408
4409        <row>
4410        <entry> <literal>\t</> </entry>
4411        <entry> horizontal tab, as in C </entry>
4412        </row>
4413
4414        <row>
4415        <entry> <literal>\u</><replaceable>wxyz</> </entry>
4416        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4417        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4418        in the local byte ordering </entry>
4419        </row>
4420
4421        <row>
4422        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4423        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4424        digits)
4425        reserved for a hypothetical Unicode extension to 32 bits
4426        </entry>
4427        </row>
4428
4429        <row>
4430        <entry> <literal>\v</> </entry>
4431        <entry> vertical tab, as in C </entry>
4432        </row>
4433
4434        <row>
4435        <entry> <literal>\x</><replaceable>hhh</> </entry>
4436        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4437        digits)
4438        the character whose hexadecimal value is
4439        <literal>0x</><replaceable>hhh</>
4440        (a single character no matter how many hexadecimal digits are used)
4441        </entry>
4442        </row>
4443
4444        <row>
4445        <entry> <literal>\0</> </entry>
4446        <entry> the character whose value is <literal>0</> (the null byte)</entry>
4447        </row>
4448
4449        <row>
4450        <entry> <literal>\</><replaceable>xy</> </entry>
4451        <entry> (where <replaceable>xy</> is exactly two octal digits,
4452        and is not a <firstterm>back reference</>)
4453        the character whose octal value is
4454        <literal>0</><replaceable>xy</> </entry>
4455        </row>
4456
4457        <row>
4458        <entry> <literal>\</><replaceable>xyz</> </entry>
4459        <entry> (where <replaceable>xyz</> is exactly three octal digits,
4460        and is not a <firstterm>back reference</>)
4461        the character whose octal value is
4462        <literal>0</><replaceable>xyz</> </entry>
4463        </row>
4464       </tbody>
4465      </tgroup>
4466     </table>
4467
4468    <para>
4469     Hexadecimal digits are <literal>0</>-<literal>9</>,
4470     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4471     Octal digits are <literal>0</>-<literal>7</>.
4472    </para>
4473
4474    <para>
4475     The character-entry escapes are always taken as ordinary characters.
4476     For example, <literal>\135</> is <literal>]</> in ASCII, but
4477     <literal>\135</> does not terminate a bracket expression.
4478    </para>
4479
4480    <table id="posix-class-shorthand-escapes-table">
4481     <title>Regular Expression Class-shorthand Escapes</title>
4482
4483     <tgroup cols="2">
4484      <thead>
4485       <row>
4486        <entry>Escape</entry>
4487        <entry>Description</entry>
4488       </row>
4489      </thead>
4490
4491       <tbody>
4492        <row>
4493        <entry> <literal>\d</> </entry>
4494        <entry> <literal>[[:digit:]]</> </entry>
4495        </row>
4496
4497        <row>
4498        <entry> <literal>\s</> </entry>
4499        <entry> <literal>[[:space:]]</> </entry>
4500        </row>
4501
4502        <row>
4503        <entry> <literal>\w</> </entry>
4504        <entry> <literal>[[:alnum:]_]</>
4505        (note underscore is included) </entry>
4506        </row>
4507
4508        <row>
4509        <entry> <literal>\D</> </entry>
4510        <entry> <literal>[^[:digit:]]</> </entry>
4511        </row>
4512
4513        <row>
4514        <entry> <literal>\S</> </entry>
4515        <entry> <literal>[^[:space:]]</> </entry>
4516        </row>
4517
4518        <row>
4519        <entry> <literal>\W</> </entry>
4520        <entry> <literal>[^[:alnum:]_]</>
4521        (note underscore is included) </entry>
4522        </row>
4523       </tbody>
4524      </tgroup>
4525     </table>
4526
4527    <para>
4528     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4529     and <literal>\w</> lose their outer brackets,
4530     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4531     (So, for example, <literal>[a-c\d]</> is equivalent to
4532     <literal>[a-c[:digit:]]</>.
4533     Also, <literal>[a-c\D]</>, which is equivalent to
4534     <literal>[a-c^[:digit:]]</>, is illegal.)
4535    </para>
4536
4537    <table id="posix-constraint-escapes-table">
4538     <title>Regular Expression Constraint Escapes</title>
4539
4540     <tgroup cols="2">
4541      <thead>
4542       <row>
4543        <entry>Escape</entry>
4544        <entry>Description</entry>
4545       </row>
4546      </thead>
4547
4548       <tbody>
4549        <row>
4550        <entry> <literal>\A</> </entry>
4551        <entry> matches only at the beginning of the string
4552        (see <xref linkend="posix-matching-rules"> for how this differs from
4553        <literal>^</>) </entry>
4554        </row>
4555
4556        <row>
4557        <entry> <literal>\m</> </entry>
4558        <entry> matches only at the beginning of a word </entry>
4559        </row>
4560
4561        <row>
4562        <entry> <literal>\M</> </entry>
4563        <entry> matches only at the end of a word </entry>
4564        </row>
4565
4566        <row>
4567        <entry> <literal>\y</> </entry>
4568        <entry> matches only at the beginning or end of a word </entry>
4569        </row>
4570
4571        <row>
4572        <entry> <literal>\Y</> </entry>
4573        <entry> matches only at a point that is not the beginning or end of a
4574        word </entry>
4575        </row>
4576
4577        <row>
4578        <entry> <literal>\Z</> </entry>
4579        <entry> matches only at the end of the string
4580        (see <xref linkend="posix-matching-rules"> for how this differs from
4581        <literal>$</>) </entry>
4582        </row>
4583       </tbody>
4584      </tgroup>
4585     </table>
4586
4587    <para>
4588     A word is defined as in the specification of
4589     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4590     Constraint escapes are illegal within bracket expressions.
4591    </para>
4592
4593    <table id="posix-constraint-backref-table">
4594     <title>Regular Expression Back References</title>
4595
4596     <tgroup cols="2">
4597      <thead>
4598       <row>
4599        <entry>Escape</entry>
4600        <entry>Description</entry>
4601       </row>
4602      </thead>
4603
4604       <tbody>
4605        <row>
4606        <entry> <literal>\</><replaceable>m</> </entry>
4607        <entry> (where <replaceable>m</> is a nonzero digit)
4608        a back reference to the <replaceable>m</>'th subexpression </entry>
4609        </row>
4610
4611        <row>
4612        <entry> <literal>\</><replaceable>mnn</> </entry>
4613        <entry> (where <replaceable>m</> is a nonzero digit, and
4614        <replaceable>nn</> is some more digits, and the decimal value
4615        <replaceable>mnn</> is not greater than the number of closing capturing
4616        parentheses seen so far)
4617        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4618        </row>
4619       </tbody>
4620      </tgroup>
4621     </table>
4622
4623    <note>
4624     <para>
4625      There is an inherent ambiguity between octal character-entry
4626      escapes and back references, which is resolved by the following heuristics,
4627      as hinted at above.
4628      A leading zero always indicates an octal escape.
4629      A single non-zero digit, not followed by another digit,
4630      is always taken as a back reference.
4631      A multi-digit sequence not starting with a zero is taken as a back
4632      reference if it comes after a suitable subexpression
4633      (i.e., the number is in the legal range for a back reference),
4634      and otherwise is taken as octal.
4635     </para>
4636    </note>
4637    </sect3>
4638
4639    <sect3 id="posix-metasyntax">
4640     <title>Regular Expression Metasyntax</title>
4641
4642    <para>
4643     In addition to the main syntax described above, there are some special
4644     forms and miscellaneous syntactic facilities available.
4645    </para>
4646
4647    <para>
4648     An RE can begin with one of two special <firstterm>director</> prefixes.
4649     If an RE begins with <literal>***:</>,
4650     the rest of the RE is taken as an ARE.  (This normally has no effect in
4651     <productname>PostgreSQL</>, since REs are assumed to be AREs;
4652     but it does have an effect if ERE or BRE mode had been specified by
4653     the <replaceable>flags</> parameter to a regex function.)
4654     If an RE begins with <literal>***=</>,
4655     the rest of the RE is taken to be a literal string,
4656     with all characters considered ordinary characters.
4657    </para>
4658
4659    <para>
4660     An ARE can begin with <firstterm>embedded options</>:
4661     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4662     (where <replaceable>xyz</> is one or more alphabetic characters)
4663     specifies options affecting the rest of the RE.
4664     These options override any previously determined options &mdash;
4665     in particular, they can override the case-sensitivity behavior implied by
4666     a regex operator, or the <replaceable>flags</> parameter to a regex
4667     function.
4668     The available option letters are
4669     shown in <xref linkend="posix-embedded-options-table">.
4670     Note that these same option letters are used in the <replaceable>flags</>
4671     parameters of regex functions.
4672    </para>
4673
4674    <table id="posix-embedded-options-table">
4675     <title>ARE Embedded-option Letters</title>
4676
4677     <tgroup cols="2">
4678      <thead>
4679       <row>
4680        <entry>Option</entry>
4681        <entry>Description</entry>
4682       </row>
4683      </thead>
4684
4685       <tbody>
4686        <row>
4687        <entry> <literal>b</> </entry>
4688        <entry> rest of RE is a BRE </entry>
4689        </row>
4690
4691        <row>
4692        <entry> <literal>c</> </entry>
4693        <entry> case-sensitive matching (overrides operator type) </entry>
4694        </row>
4695
4696        <row>
4697        <entry> <literal>e</> </entry>
4698        <entry> rest of RE is an ERE </entry>
4699        </row>
4700
4701        <row>
4702        <entry> <literal>i</> </entry>
4703        <entry> case-insensitive matching (see
4704        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4705        </row>
4706
4707        <row>
4708        <entry> <literal>m</> </entry>
4709        <entry> historical synonym for <literal>n</> </entry>
4710        </row>
4711
4712        <row>
4713        <entry> <literal>n</> </entry>
4714        <entry> newline-sensitive matching (see
4715        <xref linkend="posix-matching-rules">) </entry>
4716        </row>
4717
4718        <row>
4719        <entry> <literal>p</> </entry>
4720        <entry> partial newline-sensitive matching (see
4721        <xref linkend="posix-matching-rules">) </entry>
4722        </row>
4723
4724        <row>
4725        <entry> <literal>q</> </entry>
4726        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4727        characters </entry>
4728        </row>
4729
4730        <row>
4731        <entry> <literal>s</> </entry>
4732        <entry> non-newline-sensitive matching (default) </entry>
4733        </row>
4734
4735        <row>
4736        <entry> <literal>t</> </entry>
4737        <entry> tight syntax (default; see below) </entry>
4738        </row>
4739
4740        <row>
4741        <entry> <literal>w</> </entry>
4742        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4743        (see <xref linkend="posix-matching-rules">) </entry>
4744        </row>
4745
4746        <row>
4747        <entry> <literal>x</> </entry>
4748        <entry> expanded syntax (see below) </entry>
4749        </row>
4750       </tbody>
4751      </tgroup>
4752     </table>
4753
4754    <para>
4755     Embedded options take effect at the <literal>)</> terminating the sequence.
4756     They can appear only at the start of an ARE (after the
4757     <literal>***:</> director if any).
4758    </para>
4759
4760    <para>
4761     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4762     characters are significant, there is an <firstterm>expanded</> syntax,
4763     available by specifying the embedded <literal>x</> option.
4764     In the expanded syntax,
4765     white-space characters in the RE are ignored, as are
4766     all characters between a <literal>#</>
4767     and the following newline (or the end of the RE).  This
4768     permits paragraphing and commenting a complex RE.
4769     There are three exceptions to that basic rule:
4770
4771     <itemizedlist>
4772      <listitem>
4773       <para>
4774        a white-space character or <literal>#</> preceded by <literal>\</> is
4775        retained
4776       </para>
4777      </listitem>
4778      <listitem>
4779       <para>
4780        white space or <literal>#</> within a bracket expression is retained
4781       </para>
4782      </listitem>
4783      <listitem>
4784       <para>
4785        white space and comments cannot appear within multi-character symbols,
4786        such as <literal>(?:</>
4787       </para>
4788      </listitem>
4789     </itemizedlist>
4790
4791     For this purpose, white-space characters are blank, tab, newline, and
4792     any character that belongs to the <replaceable>space</> character class.
4793    </para>
4794
4795    <para>
4796     Finally, in an ARE, outside bracket expressions, the sequence
4797     <literal>(?#</><replaceable>ttt</><literal>)</>
4798     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4799     is a comment, completely ignored.
4800     Again, this is not allowed between the characters of
4801     multi-character symbols, like <literal>(?:</>.
4802     Such comments are more a historical artifact than a useful facility,
4803     and their use is deprecated; use the expanded syntax instead.
4804    </para>
4805
4806    <para>
4807     <emphasis>None</> of these metasyntax extensions is available if
4808     an initial <literal>***=</> director
4809     has specified that the user's input be treated as a literal string
4810     rather than as an RE.
4811    </para>
4812    </sect3>
4813
4814    <sect3 id="posix-matching-rules">
4815     <title>Regular Expression Matching Rules</title>
4816
4817    <para>
4818     In the event that an RE could match more than one substring of a given
4819     string, the RE matches the one starting earliest in the string.
4820     If the RE could match more than one substring starting at that point,
4821     either the longest possible match or the shortest possible match will
4822     be taken, depending on whether the RE is <firstterm>greedy</> or
4823     <firstterm>non-greedy</>.
4824    </para>
4825
4826    <para>
4827     Whether an RE is greedy or not is determined by the following rules:
4828     <itemizedlist>
4829      <listitem>
4830       <para>
4831        Most atoms, and all constraints, have no greediness attribute (because
4832        they cannot match variable amounts of text anyway).
4833       </para>
4834      </listitem>
4835      <listitem>
4836       <para>
4837        Adding parentheses around an RE does not change its greediness.
4838       </para>
4839      </listitem>
4840      <listitem>
4841       <para>
4842        A quantified atom with a fixed-repetition quantifier
4843        (<literal>{</><replaceable>m</><literal>}</>
4844        or
4845        <literal>{</><replaceable>m</><literal>}?</>)
4846        has the same greediness (possibly none) as the atom itself.
4847       </para>
4848      </listitem>
4849      <listitem>
4850       <para>
4851        A quantified atom with other normal quantifiers (including
4852        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4853        with <replaceable>m</> equal to <replaceable>n</>)
4854        is greedy (prefers longest match).
4855       </para>
4856      </listitem>
4857      <listitem>
4858       <para>
4859        A quantified atom with a non-greedy quantifier (including
4860        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4861        with <replaceable>m</> equal to <replaceable>n</>)
4862        is non-greedy (prefers shortest match).
4863       </para>
4864      </listitem>
4865      <listitem>
4866       <para>
4867        A branch &mdash; that is, an RE that has no top-level
4868        <literal>|</> operator &mdash; has the same greediness as the first
4869        quantified atom in it that has a greediness attribute.
4870       </para>
4871      </listitem>
4872      <listitem>
4873       <para>
4874        An RE consisting of two or more branches connected by the
4875        <literal>|</> operator is always greedy.
4876       </para>
4877      </listitem>
4878     </itemizedlist>
4879    </para>
4880
4881    <para>
4882     The above rules associate greediness attributes not only with individual
4883     quantified atoms, but with branches and entire REs that contain quantified
4884     atoms.  What that means is that the matching is done in such a way that
4885     the branch, or whole RE, matches the longest or shortest possible
4886     substring <emphasis>as a whole</>.  Once the length of the entire match
4887     is determined, the part of it that matches any particular subexpression
4888     is determined on the basis of the greediness attribute of that
4889     subexpression, with subexpressions starting earlier in the RE taking
4890     priority over ones starting later.
4891    </para>
4892
4893    <para>
4894     An example of what this means:
4895 <screen>
4896 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4897 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4898 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4899 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4900 </screen>
4901     In the first case, the RE as a whole is greedy because <literal>Y*</>
4902     is greedy.  It can match beginning at the <literal>Y</>, and it matches
4903     the longest possible string starting there, i.e., <literal>Y123</>.
4904     The output is the parenthesized part of that, or <literal>123</>.
4905     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4906     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
4907     the shortest possible string starting there, i.e., <literal>Y1</>.
4908     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4909     the decision as to the overall match length; so it is forced to match
4910     just <literal>1</>.
4911    </para>
4912
4913    <para>
4914     In short, when an RE contains both greedy and non-greedy subexpressions,
4915     the total match length is either as long as possible or as short as
4916     possible, according to the attribute assigned to the whole RE.  The
4917     attributes assigned to the subexpressions only affect how much of that
4918     match they are allowed to <quote>eat</> relative to each other.
4919    </para>
4920
4921    <para>
4922     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4923     can be used to force greediness or non-greediness, respectively,
4924     on a subexpression or a whole RE.
4925    </para>
4926
4927    <para>
4928     Match lengths are measured in characters, not collating elements.
4929     An empty string is considered longer than no match at all.
4930     For example:
4931     <literal>bb*</>
4932     matches the three middle characters of <literal>abbbc</>;
4933     <literal>(week|wee)(night|knights)</>
4934     matches all ten characters of <literal>weeknights</>;
4935     when <literal>(.*).*</>
4936     is matched against <literal>abc</> the parenthesized subexpression
4937     matches all three characters; and when
4938     <literal>(a*)*</> is matched against <literal>bc</>
4939     both the whole RE and the parenthesized
4940     subexpression match an empty string.
4941    </para>
4942
4943    <para>
4944     If case-independent matching is specified,
4945     the effect is much as if all case distinctions had vanished from the
4946     alphabet.
4947     When an alphabetic that exists in multiple cases appears as an
4948     ordinary character outside a bracket expression, it is effectively
4949     transformed into a bracket expression containing both cases,
4950     e.g., <literal>x</> becomes <literal>[xX]</>.
4951     When it appears inside a bracket expression, all case counterparts
4952     of it are added to the bracket expression, e.g.,
4953     <literal>[x]</> becomes <literal>[xX]</>
4954     and <literal>[^x]</> becomes <literal>[^xX]</>.
4955    </para>
4956
4957    <para>
4958     If newline-sensitive matching is specified, <literal>.</>
4959     and bracket expressions using <literal>^</>
4960     will never match the newline character
4961     (so that matches will never cross newlines unless the RE
4962     explicitly arranges it)
4963     and <literal>^</>and <literal>$</>
4964     will match the empty string after and before a newline
4965     respectively, in addition to matching at beginning and end of string
4966     respectively.
4967     But the ARE escapes <literal>\A</> and <literal>\Z</>
4968     continue to match beginning or end of string <emphasis>only</>.
4969    </para>
4970
4971    <para>
4972     If partial newline-sensitive matching is specified,
4973     this affects <literal>.</> and bracket expressions
4974     as with newline-sensitive matching, but not <literal>^</>
4975     and <literal>$</>.
4976    </para>
4977
4978    <para>
4979     If inverse partial newline-sensitive matching is specified,
4980     this affects <literal>^</> and <literal>$</>
4981     as with newline-sensitive matching, but not <literal>.</>
4982     and bracket expressions.
4983     This isn't very useful but is provided for symmetry.
4984    </para>
4985    </sect3>
4986
4987    <sect3 id="posix-limits-compatibility">
4988     <title>Limits and Compatibility</title>
4989
4990    <para>
4991     No particular limit is imposed on the length of REs in this
4992     implementation.  However,
4993     programs intended to be highly portable should not employ REs longer
4994     than 256 bytes,
4995     as a POSIX-compliant implementation can refuse to accept such REs.
4996    </para>
4997
4998    <para>
4999     The only feature of AREs that is actually incompatible with
5000     POSIX EREs is that <literal>\</> does not lose its special
5001     significance inside bracket expressions.
5002     All other ARE features use syntax which is illegal or has
5003     undefined or unspecified effects in POSIX EREs;
5004     the <literal>***</> syntax of directors likewise is outside the POSIX
5005     syntax for both BREs and EREs.
5006    </para>
5007
5008    <para>
5009     Many of the ARE extensions are borrowed from Perl, but some have
5010     been changed to clean them up, and a few Perl extensions are not present.
5011     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
5012     the lack of special treatment for a trailing newline,
5013     the addition of complemented bracket expressions to the things
5014     affected by newline-sensitive matching,
5015     the restrictions on parentheses and back references in lookahead
5016     constraints, and the longest/shortest-match (rather than first-match)
5017     matching semantics.
5018    </para>
5019
5020    <para>
5021     Two significant incompatibilities exist between AREs and the ERE syntax
5022     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
5023
5024     <itemizedlist>
5025      <listitem>
5026       <para>
5027        In AREs, <literal>\</> followed by an alphanumeric character is either
5028        an escape or an error, while in previous releases, it was just another
5029        way of writing the alphanumeric.
5030        This should not be much of a problem because there was no reason to
5031        write such a sequence in earlier releases.
5032       </para>
5033      </listitem>
5034      <listitem>
5035       <para>
5036        In AREs, <literal>\</> remains a special character within
5037        <literal>[]</>, so a literal <literal>\</> within a bracket
5038        expression must be written <literal>\\</>.
5039       </para>
5040      </listitem>
5041     </itemizedlist>
5042    </para>
5043    </sect3>
5044
5045    <sect3 id="posix-basic-regexes">
5046     <title>Basic Regular Expressions</title>
5047
5048    <para>
5049     BREs differ from EREs in several respects.
5050     In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
5051     are ordinary characters and there is no equivalent
5052     for their functionality.
5053     The delimiters for bounds are
5054     <literal>\{</> and <literal>\}</>,
5055     with <literal>{</> and <literal>}</>
5056     by themselves ordinary characters.
5057     The parentheses for nested subexpressions are
5058     <literal>\(</> and <literal>\)</>,
5059     with <literal>(</> and <literal>)</> by themselves ordinary characters.
5060     <literal>^</> is an ordinary character except at the beginning of the
5061     RE or the beginning of a parenthesized subexpression,
5062     <literal>$</> is an ordinary character except at the end of the
5063     RE or the end of a parenthesized subexpression,
5064     and <literal>*</> is an ordinary character if it appears at the beginning
5065     of the RE or the beginning of a parenthesized subexpression
5066     (after a possible leading <literal>^</>).
5067     Finally, single-digit back references are available, and
5068     <literal>\&lt;</> and <literal>\&gt;</>
5069     are synonyms for
5070     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
5071     respectively; no other escapes are available in BREs.
5072    </para>
5073    </sect3>
5074
5075 <!-- end re_syntax.n man page -->
5076
5077   </sect2>
5078  </sect1>
5079
5080
5081   <sect1 id="functions-formatting">
5082    <title>Data Type Formatting Functions</title>
5083
5084    <indexterm>
5085     <primary>formatting</primary>
5086    </indexterm>
5087
5088    <para>
5089     The <productname>PostgreSQL</productname> formatting functions
5090     provide a powerful set of tools for converting various data types
5091     (date/time, integer, floating point, numeric) to formatted strings
5092     and for converting from formatted strings to specific data types.
5093     <xref linkend="functions-formatting-table"> lists them.
5094     These functions all follow a common calling convention: the first
5095     argument is the value to be formatted and the second argument is a
5096     template that defines the output or input format.
5097    </para>
5098    <para>
5099     A single-argument <function>to_timestamp</function> function is also
5100     available;  it accepts a
5101     <type>double precision</type> argument and converts from Unix epoch
5102     (seconds since 1970-01-01 00:00:00+00) to
5103     <type>timestamp with time zone</type>.
5104     (<type>Integer</type> Unix epochs are implicitly cast to
5105     <type>double precision</type>.)
5106    </para>
5107
5108     <table id="functions-formatting-table">
5109      <title>Formatting Functions</title>
5110      <tgroup cols="4">
5111       <thead>
5112        <row>
5113         <entry>Function</entry>
5114         <entry>Return Type</entry>
5115         <entry>Description</entry>
5116         <entry>Example</entry>
5117        </row>
5118       </thead>
5119       <tbody>
5120        <row>
5121         <entry>
5122          <indexterm>
5123           <primary>to_char</primary>
5124          </indexterm>
5125          <literal><function>to_char(<type>timestamp</type>, <type>text</type>)</function></literal>
5126         </entry>
5127         <entry><type>text</type></entry>
5128         <entry>convert time stamp to string</entry>
5129         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
5130        </row>
5131        <row>
5132         <entry><literal><function>to_char(<type>interval</type>, <type>text</type>)</function></literal></entry>
5133         <entry><type>text</type></entry>
5134         <entry>convert interval to string</entry>
5135         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
5136        </row>
5137        <row>
5138         <entry><literal><function>to_char(<type>int</type>, <type>text</type>)</function></literal></entry>
5139         <entry><type>text</type></entry>
5140         <entry>convert integer to string</entry>
5141         <entry><literal>to_char(125, '999')</literal></entry>
5142        </row>
5143        <row>
5144         <entry><literal><function>to_char</function>(<type>double precision</type>,
5145         <type>text</type>)</literal></entry>
5146         <entry><type>text</type></entry>
5147         <entry>convert real/double precision to string</entry>
5148         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
5149        </row>
5150        <row>
5151         <entry><literal><function>to_char(<type>numeric</type>, <type>text</type>)</function></literal></entry>
5152         <entry><type>text</type></entry>
5153         <entry>convert numeric to string</entry>
5154         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
5155        </row>
5156        <row>
5157         <entry>
5158          <indexterm>
5159           <primary>to_date</primary>
5160          </indexterm>
5161          <literal><function>to_date(<type>text</type>, <type>text</type>)</function></literal>
5162         </entry>
5163         <entry><type>date</type></entry>
5164         <entry>convert string to date</entry>
5165         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5166        </row>
5167        <row>
5168         <entry>
5169          <indexterm>
5170           <primary>to_number</primary>
5171          </indexterm>
5172          <literal><function>to_number(<type>text</type>, <type>text</type>)</function></literal>
5173         </entry>
5174         <entry><type>numeric</type></entry>
5175         <entry>convert string to numeric</entry>
5176         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
5177        </row>
5178        <row>
5179         <entry>
5180          <indexterm>
5181           <primary>to_timestamp</primary>
5182          </indexterm>
5183          <literal><function>to_timestamp(<type>text</type>, <type>text</type>)</function></literal>
5184         </entry>
5185         <entry><type>timestamp with time zone</type></entry>
5186         <entry>convert string to time stamp</entry>
5187         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5188        </row>
5189        <row>
5190         <entry><literal><function>to_timestamp(<type>double precision</type>)</function></literal></entry>
5191         <entry><type>timestamp with time zone</type></entry>
5192         <entry>convert Unix epoch to time stamp</entry>
5193         <entry><literal>to_timestamp(1284352323)</literal></entry>
5194        </row>
5195       </tbody>
5196      </tgroup>
5197     </table>
5198
5199    <para>
5200     In a <function>to_char</> output template string, there are certain
5201     patterns that are recognized and replaced with appropriately-formatted
5202     data based on the given value.  Any text that is not a template pattern is
5203     simply copied verbatim.  Similarly, in an input template string (for the
5204     other functions), template patterns identify the values to be supplied by
5205     the input data string.
5206    </para>
5207
5208   <para>
5209    <xref linkend="functions-formatting-datetime-table"> shows the
5210    template patterns available for formatting date and time values.
5211   </para>
5212
5213     <table id="functions-formatting-datetime-table">
5214      <title>Template Patterns for Date/Time Formatting</title>
5215      <tgroup cols="2">
5216       <thead>
5217        <row>
5218         <entry>Pattern</entry>
5219         <entry>Description</entry>
5220        </row>
5221       </thead>
5222       <tbody>
5223        <row>
5224         <entry><literal>HH</literal></entry>
5225         <entry>hour of day (01-12)</entry>
5226        </row>
5227        <row>
5228         <entry><literal>HH12</literal></entry>
5229         <entry>hour of day (01-12)</entry>
5230        </row>
5231        <row>
5232         <entry><literal>HH24</literal></entry>
5233         <entry>hour of day (00-23)</entry>
5234        </row>
5235        <row>
5236         <entry><literal>MI</literal></entry>
5237         <entry>minute (00-59)</entry>
5238        </row>
5239        <row>
5240         <entry><literal>SS</literal></entry>
5241         <entry>second (00-59)</entry>
5242        </row>
5243        <row>
5244         <entry><literal>MS</literal></entry>
5245         <entry>millisecond (000-999)</entry>
5246        </row>
5247        <row>
5248         <entry><literal>US</literal></entry>
5249         <entry>microsecond (000000-999999)</entry>
5250        </row>
5251        <row>
5252         <entry><literal>SSSS</literal></entry>
5253         <entry>seconds past midnight (0-86399)</entry>
5254        </row>
5255        <row>
5256         <entry><literal>AM</literal>, <literal>am</literal>,
5257         <literal>PM</literal> or <literal>pm</literal></entry>
5258         <entry>meridiem indicator (without periods)</entry>
5259        </row>
5260        <row>
5261         <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
5262         <literal>P.M.</literal> or <literal>p.m.</literal></entry>
5263         <entry>meridiem indicator (with periods)</entry>
5264        </row>
5265        <row>
5266         <entry><literal>Y,YYY</literal></entry>
5267         <entry>year (4 and more digits) with comma</entry>
5268        </row>
5269        <row>
5270         <entry><literal>YYYY</literal></entry>
5271         <entry>year (4 and more digits)</entry>
5272        </row>
5273        <row>
5274         <entry><literal>YYY</literal></entry>
5275         <entry>last 3 digits of year</entry>
5276        </row>
5277        <row>
5278         <entry><literal>YY</literal></entry>
5279         <entry>last 2 digits of year</entry>
5280        </row>
5281        <row>
5282         <entry><literal>Y</literal></entry>
5283         <entry>last digit of year</entry>
5284        </row>
5285        <row>
5286         <entry><literal>IYYY</literal></entry>
5287         <entry>ISO year (4 and more digits)</entry>
5288        </row>
5289        <row>
5290         <entry><literal>IYY</literal></entry>
5291         <entry>last 3 digits of ISO year</entry>
5292        </row>
5293        <row>
5294         <entry><literal>IY</literal></entry>
5295         <entry>last 2 digits of ISO year</entry>
5296        </row>
5297        <row>
5298         <entry><literal>I</literal></entry>
5299         <entry>last digit of ISO year</entry>
5300        </row>
5301        <row>
5302         <entry><literal>BC</literal>, <literal>bc</literal>,
5303         <literal>AD</literal> or <literal>ad</literal></entry>
5304         <entry>era indicator (without periods)</entry>
5305        </row>
5306        <row>
5307         <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
5308         <literal>A.D.</literal> or <literal>a.d.</literal></entry>
5309         <entry>era indicator (with periods)</entry>
5310        </row>
5311        <row>
5312         <entry><literal>MONTH</literal></entry>
5313         <entry>full upper case month name (blank-padded to 9 chars)</entry>
5314        </row>
5315        <row>
5316         <entry><literal>Month</literal></entry>
5317         <entry>full capitalized month name (blank-padded to 9 chars)</entry>
5318        </row>
5319        <row>
5320         <entry><literal>month</literal></entry>
5321         <entry>full lower case month name (blank-padded to 9 chars)</entry>
5322        </row>
5323        <row>
5324         <entry><literal>MON</literal></entry>
5325         <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
5326        </row>
5327        <row>
5328         <entry><literal>Mon</literal></entry>
5329         <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
5330        </row>
5331        <row>
5332         <entry><literal>mon</literal></entry>
5333         <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
5334        </row>
5335        <row>
5336         <entry><literal>MM</literal></entry>
5337         <entry>month number (01-12)</entry>
5338        </row>
5339        <row>
5340         <entry><literal>DAY</literal></entry>
5341         <entry>full upper case day name (blank-padded to 9 chars)</entry>
5342        </row>
5343        <row>
5344         <entry><literal>Day</literal></entry>
5345         <entry>full capitalized day name (blank-padded to 9 chars)</entry>
5346        </row>
5347        <row>
5348         <entry><literal>day</literal></entry>
5349         <entry>full lower case day name (blank-padded to 9 chars)</entry>
5350        </row>
5351        <row>
5352         <entry><literal>DY</literal></entry>
5353         <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
5354        </row>
5355        <row>
5356         <entry><literal>Dy</literal></entry>
5357         <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
5358        </row>
5359        <row>
5360         <entry><literal>dy</literal></entry>
5361         <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
5362        </row>
5363        <row>
5364         <entry><literal>DDD</literal></entry>
5365         <entry>day of year (001-366)</entry>
5366        </row>
5367        <row>
5368         <entry><literal>IDDD</literal></entry>
5369         <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
5370        </row>
5371        <row>
5372         <entry><literal>DD</literal></entry>
5373         <entry>day of month (01-31)</entry>
5374        </row>
5375        <row>
5376         <entry><literal>D</literal></entry>
5377         <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
5378        </row>
5379        <row>
5380         <entry><literal>ID</literal></entry>
5381         <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
5382        </row>
5383        <row>
5384         <entry><literal>W</literal></entry>
5385         <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
5386        </row>
5387        <row>
5388         <entry><literal>WW</literal></entry>
5389         <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
5390        </row>
5391        <row>
5392         <entry><literal>IW</literal></entry>
5393         <entry>ISO week number of year (01 - 53; the first Thursday of the new year is in week 1.)</entry>
5394        </row>
5395        <row>
5396         <entry><literal>CC</literal></entry>
5397         <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
5398        </row>
5399        <row>
5400         <entry><literal>J</literal></entry>
5401         <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
5402        </row>
5403        <row>
5404         <entry><literal>Q</literal></entry>
5405         <entry>quarter (ignored by <function>to_date</> and <function>to_timestamp</>)</entry>
5406        </row>
5407        <row>
5408         <entry><literal>RM</literal></entry>
5409         <entry>month in upper case Roman numerals (I-XII; I=January)</entry>
5410        </row>
5411        <row>
5412         <entry><literal>rm</literal></entry>
5413         <entry>month in lower case Roman numerals (i-xii; i=January)</entry>
5414        </row>
5415        <row>
5416         <entry><literal>TZ</literal></entry>
5417         <entry>upper case time-zone name</entry>
5418        </row>
5419        <row>
5420         <entry><literal>tz</literal></entry>
5421         <entry>lower case time-zone name</entry>
5422        </row>
5423       </tbody>
5424      </tgroup>
5425     </table>
5426
5427    <para>
5428     Modifiers can be applied to any template pattern to alter its
5429     behavior.  For example, <literal>FMMonth</literal>
5430     is the <literal>Month</literal> pattern with the
5431     <literal>FM</literal> modifier.
5432     <xref linkend="functions-formatting-datetimemod-table"> shows the
5433     modifier patterns for date/time formatting.
5434    </para>
5435
5436     <table id="functions-formatting-datetimemod-table">
5437      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5438      <tgroup cols="3">
5439       <thead>
5440        <row>
5441         <entry>Modifier</entry>
5442         <entry>Description</entry>
5443         <entry>Example</entry>
5444        </row>
5445       </thead>
5446       <tbody>
5447        <row>
5448         <entry><literal>FM</literal> prefix</entry>
5449         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5450         <entry><literal>FMMonth</literal></entry>
5451        </row>
5452        <row>
5453         <entry><literal>TH</literal> suffix</entry>
5454         <entry>upper case ordinal number suffix</entry>
5455         <entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
5456        </row>
5457        <row>
5458         <entry><literal>th</literal> suffix</entry>
5459         <entry>lower case ordinal number suffix</entry>
5460         <entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
5461        </row>
5462        <row>
5463         <entry><literal>FX</literal> prefix</entry>
5464         <entry>fixed format global option (see usage notes)</entry>
5465         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5466        </row>
5467        <row>
5468         <entry><literal>TM</literal> prefix</entry>
5469         <entry>translation mode (print localized day and month names based on
5470          <xref linkend="guc-lc-time">)</entry>
5471         <entry><literal>TMMonth</literal></entry>
5472        </row>
5473        <row>
5474         <entry><literal>SP</literal> suffix</entry>
5475         <entry>spell mode (not implemented)</entry>
5476         <entry><literal>DDSP</literal></entry>
5477        </row>
5478       </tbody>
5479      </tgroup>
5480     </table>
5481
5482    <para>
5483     Usage notes for date/time formatting:
5484
5485     <itemizedlist>
5486      <listitem>
5487       <para>
5488        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5489        that would otherwise be added to make the output of a pattern be
5490        fixed-width.  In <productname>PostgreSQL</productname>,
5491        <literal>FM</literal> modifies only the next specification, while in
5492        Oracle <literal>FM</literal> affects all subsequent
5493        specifications, and repeated <literal>FM</literal> modifiers
5494        toggle fill mode on and off.
5495       </para>
5496      </listitem>
5497
5498      <listitem>
5499       <para>
5500        <literal>TM</literal> does not include trailing blanks.
5501       </para>
5502      </listitem>
5503
5504      <listitem>
5505       <para>
5506        <function>to_timestamp</function> and <function>to_date</function>
5507        skip multiple blank spaces in the input string unless the
5508        <literal>FX</literal> option is used. For example,
5509        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> works, but
5510        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
5511        because <function>to_timestamp</function> expects one space only.
5512        <literal>FX</literal> must be specified as the first item in
5513        the template.
5514       </para>
5515      </listitem>
5516
5517      <listitem>
5518       <para>
5519        Ordinary text is allowed in <function>to_char</function>
5520        templates and will be output literally.  You can put a substring
5521        in double quotes to force it to be interpreted as literal text
5522        even if it contains pattern key words.  For example, in
5523        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5524        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5525        will not be.  In <function>to_date</>, <function>to_number</>,
5526        and <function>to_timestamp</>, double-quoted strings skip the number of
5527        input characters contained in the string, e.g. <literal>"XX"</>
5528        skips two input characters.
5529       </para>
5530      </listitem>
5531
5532      <listitem>
5533       <para>
5534        If you want to have a double quote in the output you must
5535        precede it with a backslash, for example <literal>E'\\"YYYY
5536        Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
5537        (Two backslashes are necessary because the backslash
5538        has special meaning when using the escape string syntax.)
5539       </para>
5540      </listitem>
5541
5542      <listitem>
5543       <para>
5544        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5545        <type>date</type> has a restriction when processing years with more than 4 digits. You must
5546        use some non-digit character or template after <literal>YYYY</literal>,
5547        otherwise the year is always interpreted as 4 digits. For example
5548        (with the year 20000):
5549        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
5550        interpreted as a 4-digit year; instead use a non-digit
5551        separator after the year, like
5552        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5553        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5554       </para>
5555      </listitem>
5556
5557      <listitem>
5558       <para>
5559        In conversions from string to <type>timestamp</type> or
5560        <type>date</type>, the <literal>CC</literal> (century) field is ignored
5561        if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
5562        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5563        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5564        as <literal>(CC-1)*100+YY</literal>.
5565       </para>
5566      </listitem>
5567
5568      <listitem>
5569       <para>
5570        An ISO week date (as distinct from a Gregorian date) can be
5571        specified to <function>to_timestamp</function> and
5572        <function>to_date</function> in one of two ways:
5573        <itemizedlist>
5574         <listitem>
5575          <para>
5576           Year, week, and weekday:  for example <literal>to_date('2006-42-4',
5577           'IYYY-IW-ID')</literal> returns the date
5578           <literal>2006-10-19</literal>.  If you omit the weekday it
5579           is assumed to be 1 (Monday).
5580          </para>
5581         </listitem>
5582         <listitem>
5583          <para>
5584           Year and day of year:  for example <literal>to_date('2006-291',
5585           'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5586          </para>
5587         </listitem>
5588        </itemizedlist>
5589       </para>
5590       <para>
5591        Attempting to construct a date using a mixture of ISO week and
5592        Gregorian date fields is nonsensical, and will cause an error.  In the
5593        context of an ISO year, the concept of a <quote>month</> or <quote>day
5594        of month</> has no meaning.  In the context of a Gregorian year, the
5595        ISO week has no meaning.  Users should avoid mixing Gregorian and
5596        ISO date specifications.
5597       </para>
5598      </listitem>
5599
5600      <listitem>
5601       <para>
5602        In a conversion from string to <type>timestamp</type>, millisecond
5603        (<literal>MS</literal>) or microsecond (<literal>US</literal>)
5604        values are used as the
5605        seconds digits after the decimal point. For example
5606        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5607        but 300, because the conversion counts it as 12 + 0.3 seconds.
5608        This means for the format <literal>SS:MS</literal>, the input values
5609        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5610        same number of milliseconds. To get three milliseconds, one must use
5611        <literal>12:003</literal>, which the conversion counts as
5612        12 + 0.003 = 12.003 seconds.
5613       </para>
5614
5615       <para>
5616        Here is a more
5617        complex example:
5618        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5619        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5620        1230 microseconds = 2.021230 seconds.
5621       </para>
5622      </listitem>
5623
5624      <listitem>
5625       <para>
5626         <function>to_char(..., 'ID')</function>'s day of the week numbering
5627         matches the <function>extract(isodow from ...)</function> function, but
5628         <function>to_char(..., 'D')</function>'s does not match
5629         <function>extract(dow from ...)</function>'s day numbering.
5630       </para>
5631      </listitem>
5632
5633      <listitem>
5634       <para>
5635         <function>to_char(interval)</function> formats <literal>HH</> and
5636         <literal>HH12</> as shown on a 12-hour clock, i.e. zero hours
5637         and 36 hours output as <literal>12</>, while <literal>HH24</>
5638         outputs the full hour value, which can exceed 23 for intervals.
5639       </para>
5640      </listitem>
5641
5642     </itemizedlist>
5643    </para>
5644
5645   <para>
5646    <xref linkend="functions-formatting-numeric-table"> shows the
5647    template patterns available for formatting numeric values.
5648   </para>
5649
5650     <table id="functions-formatting-numeric-table">
5651      <title>Template Patterns for Numeric Formatting</title>
5652      <tgroup cols="2">
5653       <thead>
5654        <row>
5655         <entry>Pattern</entry>
5656         <entry>Description</entry>
5657        </row>
5658       </thead>
5659       <tbody>
5660        <row>
5661         <entry><literal>9</literal></entry>
5662         <entry>value with the specified number of digits</entry>
5663        </row>
5664        <row>
5665         <entry><literal>0</literal></entry>
5666         <entry>value with leading zeros</entry>
5667        </row>
5668        <row>
5669         <entry><literal>.</literal> (period)</entry>
5670         <entry>decimal point</entry>
5671        </row>
5672        <row>
5673         <entry><literal>,</literal> (comma)</entry>
5674         <entry>group (thousand) separator</entry>
5675        </row>
5676        <row>
5677         <entry><literal>PR</literal></entry>
5678         <entry>negative value in angle brackets</entry>
5679        </row>
5680        <row>
5681         <entry><literal>S</literal></entry>
5682         <entry>sign anchored to number (uses locale)</entry>
5683        </row>
5684        <row>
5685         <entry><literal>L</literal></entry>
5686         <entry>currency symbol (uses locale)</entry>
5687        </row>
5688        <row>
5689         <entry><literal>D</literal></entry>
5690         <entry>decimal point (uses locale)</entry>
5691        </row>
5692        <row>
5693         <entry><literal>G</literal></entry>
5694         <entry>group separator (uses locale)</entry>
5695        </row>
5696        <row>
5697         <entry><literal>MI</literal></entry>
5698         <entry>minus sign in specified position (if number &lt; 0)</entry>
5699        </row>
5700        <row>
5701         <entry><literal>PL</literal></entry>
5702         <entry>plus sign in specified position (if number &gt; 0)</entry>
5703        </row>
5704        <row>
5705         <entry><literal>SG</literal></entry>
5706         <entry>plus/minus sign in specified position</entry>
5707        </row>
5708        <row>
5709         <entry><literal>RN</literal></entry>
5710         <entry>Roman numeral (input between 1 and 3999)</entry>
5711        </row>
5712        <row>
5713         <entry><literal>TH</literal> or <literal>th</literal></entry>
5714         <entry>ordinal number suffix</entry>
5715        </row>
5716        <row>
5717         <entry><literal>V</literal></entry>
5718         <entry>shift specified number of digits (see notes)</entry>
5719        </row>
5720        <row>
5721         <entry><literal>EEEE</literal></entry>
5722         <entry>exponent for scientific notation</entry>
5723        </row>
5724       </tbody>
5725      </tgroup>
5726     </table>
5727
5728    <para>
5729     Usage notes for numeric formatting:
5730
5731     <itemizedlist>
5732      <listitem>
5733       <para>
5734        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5735        <literal>MI</literal> is not anchored to
5736        the number; for example,
5737        <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
5738        but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
5739        The Oracle implementation does not allow the use of
5740        <literal>MI</literal> before <literal>9</literal>, but rather
5741        requires that <literal>9</literal> precede
5742        <literal>MI</literal>.
5743       </para>
5744      </listitem>
5745
5746      <listitem>
5747       <para>
5748        <literal>9</literal> results in a value with the same number of
5749        digits as there are <literal>9</literal>s. If a digit is
5750        not available it outputs a space.
5751       </para>
5752      </listitem>
5753
5754      <listitem>
5755       <para>
5756        <literal>TH</literal> does not convert values less than zero
5757        and does not convert fractional numbers.
5758       </para>
5759      </listitem>
5760
5761      <listitem>
5762       <para>
5763        <literal>PL</literal>, <literal>SG</literal>, and
5764        <literal>TH</literal> are <productname>PostgreSQL</productname>
5765        extensions.
5766       </para>
5767      </listitem>
5768
5769      <listitem>
5770       <para>
5771        <literal>V</literal> effectively
5772        multiplies the input values by
5773        <literal>10^<replaceable>n</replaceable></literal>, where
5774        <replaceable>n</replaceable> is the number of digits following
5775        <literal>V</literal>.
5776        <function>to_char</function> does not support the use of
5777        <literal>V</literal> combined with a decimal point
5778        (e.g., <literal>99.9V99</literal> is not allowed).
5779       </para>
5780      </listitem>
5781
5782      <listitem>
5783       <para>
5784        <literal>EEEE</literal> (scientific notation) cannot be used in
5785        combination with any of the other formatting patterns or
5786        modifiers other than digit and decimal point patterns, and must be at the end of the format string
5787        (e.g., <literal>9.99EEEE</literal> is a valid pattern).
5788       </para>
5789      </listitem>
5790     </itemizedlist>
5791    </para>
5792
5793    <para>
5794     Certain modifiers can be applied to any template pattern to alter its
5795     behavior.  For example, <literal>FM9999</literal>
5796     is the <literal>9999</literal> pattern with the
5797     <literal>FM</literal> modifier.
5798     <xref linkend="functions-formatting-numericmod-table"> shows the
5799     modifier patterns for numeric formatting.
5800    </para>
5801
5802     <table id="functions-formatting-numericmod-table">
5803      <title>Template Pattern Modifiers for Numeric Formatting</title>
5804      <tgroup cols="3">
5805       <thead>
5806        <row>
5807         <entry>Modifier</entry>
5808         <entry>Description</entry>
5809         <entry>Example</entry>
5810        </row>
5811       </thead>
5812       <tbody>
5813        <row>
5814         <entry><literal>FM</literal> prefix</entry>
5815         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5816         <entry><literal>FM9999</literal></entry>
5817        </row>
5818        <row>
5819         <entry><literal>TH</literal> suffix</entry>
5820         <entry>upper case ordinal number suffix</entry>
5821         <entry><literal>999TH</literal></entry>
5822        </row>
5823        <row>
5824         <entry><literal>th</literal> suffix</entry>
5825         <entry>lower case ordinal number suffix</entry>
5826         <entry><literal>999th</literal></entry>
5827        </row>
5828       </tbody>
5829      </tgroup>
5830     </table>
5831
5832   <para>
5833    <xref linkend="functions-formatting-examples-table"> shows some
5834    examples of the use of the <function>to_char</function> function.
5835   </para>
5836
5837     <table id="functions-formatting-examples-table">
5838      <title><function>to_char</function> Examples</title>
5839      <tgroup cols="2">
5840       <thead>
5841        <row>
5842         <entry>Expression</entry>
5843         <entry>Result</entry>
5844        </row>
5845       </thead>
5846       <tbody>
5847        <row>
5848         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5849         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
5850        </row>
5851        <row>
5852         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5853         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
5854        </row>
5855        <row>
5856         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5857         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
5858        </row>
5859        <row>
5860         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5861         <entry><literal>'-.1'</literal></entry>
5862        </row>
5863        <row>
5864         <entry><literal>to_char(0.1, '0.9')</literal></entry>
5865         <entry><literal>'&nbsp;0.1'</literal></entry>
5866        </row>
5867        <row>
5868         <entry><literal>to_char(12, '9990999.9')</literal></entry>
5869         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
5870        </row>
5871        <row>
5872         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5873         <entry><literal>'0012.'</literal></entry>
5874        </row>
5875        <row>
5876         <entry><literal>to_char(485, '999')</literal></entry>
5877         <entry><literal>'&nbsp;485'</literal></entry>
5878        </row>
5879        <row>
5880         <entry><literal>to_char(-485, '999')</literal></entry>
5881         <entry><literal>'-485'</literal></entry>
5882        </row>
5883        <row>
5884         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
5885         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
5886        </row>
5887        <row>
5888         <entry><literal>to_char(1485, '9,999')</literal></entry>
5889         <entry><literal>'&nbsp;1,485'</literal></entry>
5890        </row>
5891        <row>
5892         <entry><literal>to_char(1485, '9G999')</literal></entry>
5893         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
5894        </row>
5895        <row>
5896         <entry><literal>to_char(148.5, '999.999')</literal></entry>
5897         <entry><literal>'&nbsp;148.500'</literal></entry>
5898        </row>
5899        <row>
5900         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5901         <entry><literal>'148.5'</literal></entry>
5902        </row>
5903        <row>
5904         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5905         <entry><literal>'148.500'</literal></entry>
5906        </row>
5907        <row>
5908         <entry><literal>to_char(148.5, '999D999')</literal></entry>
5909         <entry><literal>'&nbsp;148,500'</literal></entry>
5910        </row>
5911        <row>
5912         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5913         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
5914        </row>
5915        <row>
5916         <entry><literal>to_char(-485, '999S')</literal></entry>
5917         <entry><literal>'485-'</literal></entry>
5918        </row>
5919        <row>
5920         <entry><literal>to_char(-485, '999MI')</literal></entry>
5921         <entry><literal>'485-'</literal></entry>
5922        </row>
5923        <row>
5924         <entry><literal>to_char(485, '999MI')</literal></entry>
5925         <entry><literal>'485&nbsp;'</literal></entry>
5926        </row>
5927        <row>
5928         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5929         <entry><literal>'485'</literal></entry>
5930        </row>
5931        <row>
5932         <entry><literal>to_char(485, 'PL999')</literal></entry>
5933         <entry><literal>'+485'</literal></entry>
5934        </row>
5935        <row>
5936         <entry><literal>to_char(485, 'SG999')</literal></entry>
5937         <entry><literal>'+485'</literal></entry>
5938        </row>
5939        <row>
5940         <entry><literal>to_char(-485, 'SG999')</literal></entry>
5941         <entry><literal>'-485'</literal></entry>
5942        </row>
5943        <row>
5944         <entry><literal>to_char(-485, '9SG99')</literal></entry>
5945         <entry><literal>'4-85'</literal></entry>
5946        </row>
5947        <row>
5948         <entry><literal>to_char(-485, '999PR')</literal></entry>
5949         <entry><literal>'&lt;485&gt;'</literal></entry>
5950        </row>
5951        <row>
5952         <entry><literal>to_char(485, 'L999')</literal></entry>
5953         <entry><literal>'DM&nbsp;485</literal></entry>
5954        </row>
5955        <row>
5956         <entry><literal>to_char(485, 'RN')</literal></entry>
5957         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
5958        </row>
5959        <row>
5960         <entry><literal>to_char(485, 'FMRN')</literal></entry>
5961         <entry><literal>'CDLXXXV'</literal></entry>
5962        </row>
5963        <row>
5964         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5965         <entry><literal>'V'</literal></entry>
5966        </row>
5967        <row>
5968         <entry><literal>to_char(482, '999th')</literal></entry>
5969         <entry><literal>'&nbsp;482nd'</literal></entry>
5970        </row>
5971        <row>
5972         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
5973         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
5974        </row>
5975        <row>
5976         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
5977         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
5978        </row>
5979        <row>
5980         <entry><literal>to_char(12, '99V999')</literal></entry>
5981         <entry><literal>'&nbsp;12000'</literal></entry>
5982        </row>
5983        <row>
5984         <entry><literal>to_char(12.4, '99V999')</literal></entry>
5985         <entry><literal>'&nbsp;12400'</literal></entry>
5986        </row>
5987        <row>
5988         <entry><literal>to_char(12.45, '99V9')</literal></entry>
5989         <entry><literal>'&nbsp;125'</literal></entry>
5990        </row>
5991        <row>
5992         <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
5993         <entry><literal>' 4.86e-04'</literal></entry>
5994        </row>
5995       </tbody>
5996      </tgroup>
5997     </table>
5998
5999   </sect1>
6000
6001
6002   <sect1 id="functions-datetime">
6003    <title>Date/Time Functions and Operators</title>
6004
6005   <para>
6006    <xref linkend="functions-datetime-table"> shows the available
6007    functions for date/time value processing, with details appearing in
6008    the following subsections.  <xref
6009    linkend="operators-datetime-table"> illustrates the behaviors of
6010    the basic arithmetic operators (<literal>+</literal>,
6011    <literal>*</literal>, etc.).  For formatting functions, refer to
6012    <xref linkend="functions-formatting">.  You should be familiar with
6013    the background information on date/time data types from <xref
6014    linkend="datatype-datetime">.
6015   </para>
6016
6017   <para>
6018    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
6019    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
6020    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
6021    For brevity, these variants are not shown separately.  Also, the
6022    <literal>+</> and <literal>*</> operators come in commutative pairs (for
6023    example both date + integer and integer + date); we show only one of each
6024    such pair.
6025   </para>
6026
6027     <table id="operators-datetime-table">
6028      <title>Date/Time Operators</title>
6029
6030      <tgroup cols="3">
6031       <thead>
6032        <row>
6033         <entry>Operator</entry>
6034         <entry>Example</entry>
6035         <entry>Result</entry>
6036        </row>
6037       </thead>
6038
6039       <tbody>
6040        <row>
6041         <entry> <literal>+</literal> </entry>
6042         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
6043         <entry><literal>date '2001-10-05'</literal></entry>
6044        </row>
6045
6046        <row>
6047         <entry> <literal>+</literal> </entry>
6048         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
6049         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
6050        </row>
6051
6052        <row>
6053         <entry> <literal>+</literal> </entry>
6054         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
6055         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
6056        </row>
6057
6058        <row>
6059         <entry> <literal>+</literal> </entry>
6060         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
6061         <entry><literal>interval '1 day 01:00:00'</literal></entry>
6062        </row>
6063
6064        <row>
6065         <entry> <literal>+</literal> </entry>
6066         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
6067         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
6068        </row>
6069
6070        <row>
6071         <entry> <literal>+</literal> </entry>
6072         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
6073         <entry><literal>time '04:00:00'</literal></entry>
6074        </row>
6075
6076        <row>
6077         <entry> <literal>-</literal> </entry>
6078         <entry><literal>- interval '23 hours'</literal></entry>
6079         <entry><literal>interval '-23:00:00'</literal></entry>
6080        </row>
6081
6082        <row>
6083         <entry> <literal>-</literal> </entry>
6084         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
6085         <entry><literal>integer '3'</literal> (days)</entry>
6086        </row>
6087
6088        <row>
6089         <entry> <literal>-</literal> </entry>
6090         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
6091         <entry><literal>date '2001-09-24'</literal></entry>
6092        </row>
6093
6094        <row>
6095         <entry> <literal>-</literal> </entry>
6096         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
6097         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
6098        </row>
6099
6100        <row>
6101         <entry> <literal>-</literal> </entry>
6102         <entry><literal>time '05:00' - time '03:00'</literal></entry>
6103         <entry><literal>interval '02:00:00'</literal></entry>
6104        </row>
6105
6106        <row>
6107         <entry> <literal>-</literal> </entry>
6108         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
6109         <entry><literal>time '03:00:00'</literal></entry>
6110        </row>
6111
6112        <row>
6113         <entry> <literal>-</literal> </entry>
6114         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
6115         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
6116        </row>
6117
6118        <row>
6119         <entry> <literal>-</literal> </entry>
6120         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
6121         <entry><literal>interval '1 day -01:00:00'</literal></entry>
6122        </row>
6123
6124        <row>
6125         <entry> <literal>-</literal> </entry>
6126         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
6127         <entry><literal>interval '1 day 15:00:00'</literal></entry>
6128        </row>
6129
6130        <row>
6131         <entry> <literal>*</literal> </entry>
6132         <entry><literal>900 * interval '1 second'</literal></entry>
6133         <entry><literal>interval '00:15:00'</literal></entry>
6134        </row>
6135
6136        <row>
6137         <entry> <literal>*</literal> </entry>
6138         <entry><literal>21 * interval '1 day'</literal></entry>
6139         <entry><literal>interval '21 days'</literal></entry>
6140        </row>
6141
6142        <row>
6143         <entry> <literal>*</literal> </entry>
6144         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
6145         <entry><literal>interval '03:30:00'</literal></entry>
6146        </row>
6147
6148        <row>
6149         <entry> <literal>/</literal> </entry>
6150         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
6151         <entry><literal>interval '00:40:00'</literal></entry>
6152        </row>
6153       </tbody>
6154      </tgroup>
6155     </table>
6156
6157     <table id="functions-datetime-table">
6158      <title>Date/Time Functions</title>
6159      <tgroup cols="5">
6160       <thead>
6161        <row>
6162         <entry>Function</entry>
6163         <entry>Return Type</entry>
6164         <entry>Description</entry>
6165         <entry>Example</entry>
6166         <entry>Result</entry>
6167        </row>
6168       </thead>
6169
6170       <tbody>
6171        <row>
6172         <entry>
6173          <indexterm>
6174           <primary>age</primary>
6175          </indexterm>
6176          <literal><function>age(<type>timestamp</type>, <type>timestamp</type>)</function></literal>
6177         </entry>
6178         <entry><type>interval</type></entry>
6179         <entry>Subtract arguments, producing a <quote>symbolic</> result that
6180         uses years and months</entry>
6181         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
6182         <entry><literal>43 years 9 mons 27 days</literal></entry>
6183        </row>
6184
6185        <row>
6186         <entry><literal><function>age(<type>timestamp</type>)</function></literal></entry>
6187         <entry><type>interval</type></entry>
6188         <entry>Subtract from <function>current_date</function> (at midnight)</entry>
6189         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
6190         <entry><literal>43 years 8 mons 3 days</literal></entry>
6191        </row>
6192
6193        <row>
6194         <entry>
6195          <indexterm>
6196           <primary>clock_timestamp</primary>
6197          </indexterm>
6198          <literal><function>clock_timestamp()</function></literal>
6199         </entry>
6200         <entry><type>timestamp with time zone</type></entry>
6201         <entry>Current date and time (changes during statement execution);
6202          see <xref linkend="functions-datetime-current">
6203         </entry>
6204         <entry></entry>
6205         <entry></entry>
6206        </row>
6207
6208        <row>
6209         <entry>
6210          <indexterm>
6211           <primary>current_date</primary>
6212          </indexterm>
6213          <literal><function>current_date</function></literal>
6214         </entry>
6215         <entry><type>date</type></entry>
6216         <entry>Current date;
6217          see <xref linkend="functions-datetime-current">
6218         </entry>
6219         <entry></entry>
6220         <entry></entry>
6221        </row>
6222
6223        <row>
6224         <entry>
6225          <indexterm>
6226           <primary>current_time</primary>
6227          </indexterm>
6228          <literal><function>current_time</function></literal>
6229         </entry>
6230         <entry><type>time with time zone</type></entry>
6231         <entry>Current time of day;
6232          see <xref linkend="functions-datetime-current">
6233         </entry>
6234         <entry></entry>
6235         <entry></entry>
6236        </row>
6237
6238        <row>
6239         <entry>
6240          <indexterm>
6241           <primary>current_timestamp</primary>
6242          </indexterm>
6243          <literal><function>current_timestamp</function></literal>
6244         </entry>
6245         <entry><type>timestamp with time zone</type></entry>
6246         <entry>Current date and time (start of current transaction);
6247          see <xref linkend="functions-datetime-current">
6248         </entry>
6249         <entry></entry>
6250         <entry></entry>
6251        </row>
6252
6253        <row>
6254         <entry>
6255          <indexterm>
6256           <primary>date_part</primary>
6257          </indexterm>
6258          <literal><function>date_part(<type>text</type>, <type>timestamp</type>)</function></literal>
6259         </entry>
6260         <entry><type>double precision</type></entry>
6261         <entry>Get subfield (equivalent to <function>extract</function>);
6262          see <xref linkend="functions-datetime-extract">
6263         </entry>
6264         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6265         <entry><literal>20</literal></entry>
6266        </row>
6267
6268        <row>
6269         <entry><literal><function>date_part(<type>text</type>, <type>interval</type>)</function></literal></entry>
6270         <entry><type>double precision</type></entry>
6271         <entry>Get subfield (equivalent to
6272          <function>extract</function>); see <xref linkend="functions-datetime-extract">
6273         </entry>
6274         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
6275         <entry><literal>3</literal></entry>
6276        </row>
6277
6278        <row>
6279         <entry>
6280          <indexterm>
6281           <primary>date_trunc</primary>
6282          </indexterm>
6283          <literal><function>date_trunc(<type>text</type>, <type>timestamp</type>)</function></literal>
6284         </entry>
6285         <entry><type>timestamp</type></entry>
6286         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
6287         </entry>
6288         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6289         <entry><literal>2001-02-16 20:00:00</literal></entry>
6290        </row>
6291
6292        <row>
6293         <entry>
6294          <indexterm>
6295           <primary>extract</primary>
6296          </indexterm>
6297          <literal><function>extract</function>(<parameter>field</parameter> from
6298          <type>timestamp</type>)</literal>
6299         </entry>
6300         <entry><type>double precision</type></entry>
6301         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6302         </entry>
6303         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
6304         <entry><literal>20</literal></entry>
6305        </row>
6306
6307        <row>
6308         <entry><literal><function>extract</function>(<parameter>field</parameter> from
6309          <type>interval</type>)</literal></entry>
6310         <entry><type>double precision</type></entry>
6311         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
6312         </entry>
6313         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
6314         <entry><literal>3</literal></entry>
6315        </row>
6316
6317        <row>
6318         <entry>
6319          <indexterm>
6320           <primary>isfinite</primary>
6321          </indexterm>
6322          <literal><function>isfinite(<type>date</type>)</function></literal>
6323         </entry>
6324         <entry><type>boolean</type></entry>
6325         <entry>Test for finite date (not +/-infinity)</entry>
6326         <entry><literal>isfinite(date '2001-02-16')</literal></entry>
6327         <entry><literal>true</literal></entry>
6328        </row>
6329
6330        <row>
6331         <entry><literal><function>isfinite(<type>timestamp</type>)</function></literal></entry>
6332         <entry><type>boolean</type></entry>
6333         <entry>Test for finite time stamp (not +/-infinity)</entry>
6334         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
6335         <entry><literal>true</literal></entry>
6336        </row>
6337
6338        <row>
6339         <entry><literal><function>isfinite(<type>interval</type>)</function></literal></entry>
6340         <entry><type>boolean</type></entry>
6341         <entry>Test for finite interval</entry>
6342         <entry><literal>isfinite(interval '4 hours')</literal></entry>
6343         <entry><literal>true</literal></entry>
6344        </row>
6345
6346        <row>
6347         <entry>
6348          <indexterm>
6349           <primary>justify_days</primary>
6350          </indexterm>
6351          <literal><function>justify_days(<type>interval</type>)</function></literal>
6352         </entry>
6353         <entry><type>interval</type></entry>
6354         <entry>Adjust interval so 30-day time periods are represented as months</entry>
6355         <entry><literal>justify_days(interval '35 days')</literal></entry>
6356         <entry><literal>1 mon 5 days</literal></entry>
6357        </row>
6358
6359        <row>
6360         <entry>
6361          <indexterm>
6362           <primary>justify_hours</primary>
6363          </indexterm>
6364          <literal><function>justify_hours(<type>interval</type>)</function></literal>
6365         </entry>
6366         <entry><type>interval</type></entry>
6367         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
6368         <entry><literal>justify_hours(interval '27 hours')</literal></entry>
6369         <entry><literal>1 day 03:00:00</literal></entry>
6370        </row>
6371
6372        <row>
6373         <entry>
6374          <indexterm>
6375           <primary>justify_interval</primary>
6376          </indexterm>
6377          <literal><function>justify_interval(<type>interval</type>)</function></literal>
6378         </entry>
6379         <entry><type>interval</type></entry>
6380         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
6381         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
6382         <entry><literal>29 days 23:00:00</literal></entry>
6383        </row>
6384
6385        <row>
6386         <entry>
6387          <indexterm>
6388           <primary>localtime</primary>
6389          </indexterm>
6390          <literal><function>localtime</function></literal>
6391         </entry>
6392         <entry><type>time</type></entry>
6393         <entry>Current time of day;
6394          see <xref linkend="functions-datetime-current">
6395         </entry>
6396         <entry></entry>
6397         <entry></entry>
6398        </row>
6399
6400        <row>
6401         <entry>
6402          <indexterm>
6403           <primary>localtimestamp</primary>
6404          </indexterm>
6405          <literal><function>localtimestamp</function></literal>
6406         </entry>
6407         <entry><type>timestamp</type></entry>
6408         <entry>Current date and time (start of current transaction);
6409          see <xref linkend="functions-datetime-current">
6410         </entry>
6411         <entry></entry>
6412         <entry></entry>
6413        </row>
6414
6415        <row>
6416         <entry>
6417          <indexterm>
6418           <primary>now</primary>
6419          </indexterm>
6420          <literal><function>now()</function></literal>
6421         </entry>
6422         <entry><type>timestamp with time zone</type></entry>
6423         <entry>Current date and time (start of current transaction);
6424          see <xref linkend="functions-datetime-current">
6425         </entry>
6426         <entry></entry>
6427         <entry></entry>
6428        </row>
6429
6430        <row>
6431         <entry>
6432          <indexterm>
6433           <primary>statement_timestamp</primary>
6434          </indexterm>
6435          <literal><function>statement_timestamp()</function></literal>
6436         </entry>
6437         <entry><type>timestamp with time zone</type></entry>
6438         <entry>Current date and time (start of current statement);
6439          see <xref linkend="functions-datetime-current">
6440         </entry>
6441         <entry></entry>
6442         <entry></entry>
6443        </row>
6444
6445        <row>
6446         <entry>
6447          <indexterm>
6448           <primary>timeofday</primary>
6449          </indexterm>
6450          <literal><function>timeofday()</function></literal>
6451         </entry>
6452         <entry><type>text</type></entry>
6453         <entry>Current date and time
6454          (like <function>clock_timestamp</>, but as a <type>text</> string);
6455          see <xref linkend="functions-datetime-current">
6456         </entry>
6457         <entry></entry>
6458         <entry></entry>
6459        </row>
6460
6461        <row>
6462         <entry>
6463          <indexterm>
6464           <primary>transaction_timestamp</primary>
6465          </indexterm>
6466          <literal><function>transaction_timestamp()</function></literal>
6467         </entry>
6468         <entry><type>timestamp with time zone</type></entry>
6469         <entry>Current date and time (start of current transaction);
6470          see <xref linkend="functions-datetime-current">
6471         </entry>
6472         <entry></entry>
6473         <entry></entry>
6474        </row>
6475       </tbody>
6476      </tgroup>
6477     </table>
6478
6479    <para>
6480     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6481     supported:
6482 <synopsis>
6483 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6484 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6485 </synopsis>
6486     This expression yields true when two time periods (defined by their
6487     endpoints) overlap, false when they do not overlap.  The endpoints
6488     can be specified as pairs of dates, times, or time stamps; or as
6489     a date, time, or time stamp followed by an interval.  When a pair
6490     of values is provided, either the start or the end can be written
6491     first; <literal>OVERLAPS</> automatically takes the earlier value
6492     of the pair as the start.  Each time period is considered to
6493     represent the half-open interval <replaceable>start</> <literal>&lt;=</>
6494     <replaceable>time</> <literal>&lt;</> <replaceable>end</>, unless
6495     <replaceable>start</> and <replaceable>end</> are equal in which case it
6496     represents that single time instant.  This means for instance that two
6497     time periods with only an endpoint in common do not overlap.
6498    </para>
6499
6500 <screen>
6501 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6502        (DATE '2001-10-30', DATE '2002-10-30');
6503 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6504 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6505        (DATE '2001-10-30', DATE '2002-10-30');
6506 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6507 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
6508        (DATE '2001-10-30', DATE '2001-10-31');
6509 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6510 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
6511        (DATE '2001-10-30', DATE '2001-10-31');
6512 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6513 </screen>
6514
6515   <para>
6516    When adding an <type>interval</type> value to (or subtracting an
6517    <type>interval</type> value from) a <type>timestamp with time zone</type>
6518    value, the days component advances (or decrements) the date of the
6519    <type>timestamp with time zone</type> by the indicated number of days.
6520    Across daylight saving time changes (with the session time zone set to a
6521    time zone that recognizes DST), this means <literal>interval '1 day'</literal>
6522    does not necessarily equal <literal>interval '24 hours'</literal>.
6523    For example, with the session time zone set to <literal>CST7CDT</literal>,
6524    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
6525    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>,
6526    while adding <literal>interval '24 hours'</literal> to the same initial
6527    <type>timestamp with time zone</type> produces
6528    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6529    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone
6530    <literal>CST7CDT</literal>.
6531   </para>
6532
6533   <para>
6534    Note there can be ambiguity in the <literal>months</> returned by
6535    <function>age</> because different months have a different number of
6536    days.  <productname>PostgreSQL</>'s approach uses the month from the
6537    earlier of the two dates when calculating partial months.  For example,
6538    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6539    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6540    days</> because May has 31 days, while April has only 30.
6541   </para>
6542
6543   <sect2 id="functions-datetime-extract">
6544    <title><function>EXTRACT</function>, <function>date_part</function></title>
6545
6546    <indexterm>
6547     <primary>date_part</primary>
6548    </indexterm>
6549    <indexterm>
6550     <primary>extract</primary>
6551    </indexterm>
6552
6553 <synopsis>
6554 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6555 </synopsis>
6556
6557    <para>
6558     The <function>extract</function> function retrieves subfields
6559     such as year or hour from date/time values.
6560     <replaceable>source</replaceable> must be a value expression of
6561     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6562     (Expressions of type <type>date</type> are
6563     cast to <type>timestamp</type> and can therefore be used as
6564     well.)  <replaceable>field</replaceable> is an identifier or
6565     string that selects what field to extract from the source value.
6566     The <function>extract</function> function returns values of type
6567     <type>double precision</type>.
6568     The following are valid field names:
6569
6570     <!-- alphabetical -->
6571     <variablelist>
6572      <varlistentry>
6573       <term><literal>century</literal></term>
6574       <listitem>
6575        <para>
6576         The century
6577        </para>
6578
6579 <screen>
6580 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6581 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6582 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6583 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6584 </screen>
6585
6586        <para>
6587         The first century starts at 0001-01-01 00:00:00 AD, although
6588         they did not know it at the time. This definition applies to all
6589         Gregorian calendar countries. There is no century number 0,
6590         you go from -1 century to 1 century.
6591
6592         If you disagree with this, please write your complaint to:
6593         Pope, Cathedral Saint-Peter of Roma, Vatican.
6594        </para>
6595
6596        <para>
6597         <productname>PostgreSQL</productname> releases before 8.0 did not
6598         follow the conventional numbering of centuries, but just returned
6599         the year field divided by 100.
6600        </para>
6601       </listitem>
6602      </varlistentry>
6603
6604      <varlistentry>
6605       <term><literal>day</literal></term>
6606       <listitem>
6607        <para>
6608         The day (of the month) field (1 - 31)
6609        </para>
6610
6611 <screen>
6612 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6613 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6614 </screen>
6615       </listitem>
6616      </varlistentry>
6617
6618      <varlistentry>
6619       <term><literal>decade</literal></term>
6620       <listitem>
6621        <para>
6622         The year field divided by 10
6623        </para>
6624
6625 <screen>
6626 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6627 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6628 </screen>
6629       </listitem>
6630      </varlistentry>
6631
6632      <varlistentry>
6633       <term><literal>dow</literal></term>
6634       <listitem>
6635        <para>
6636         The day of the week as Sunday(<literal>0</>) to
6637         Saturday(<literal>6</>)
6638        </para>
6639
6640 <screen>
6641 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6642 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6643 </screen>
6644        <para>
6645         Note that <function>extract</function>'s day of the week numbering
6646         differs from that of the <function>to_char(...,
6647         'D')</function> function.
6648        </para>
6649
6650       </listitem>
6651      </varlistentry>
6652
6653      <varlistentry>
6654       <term><literal>doy</literal></term>
6655       <listitem>
6656        <para>
6657         The day of the year (1 - 365/366)
6658        </para>
6659
6660 <screen>
6661 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6662 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6663 </screen>
6664       </listitem>
6665      </varlistentry>
6666
6667      <varlistentry>
6668       <term><literal>epoch</literal></term>
6669       <listitem>
6670        <para>
6671         For <type>date</type> and <type>timestamp</type> values, the
6672         number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
6673         for <type>interval</type> values, the total number
6674         of seconds in the interval
6675        </para>
6676
6677 <screen>
6678 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
6679 <lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput>
6680
6681 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6682 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6683 </screen>
6684
6685        <para>
6686         Here is how you can convert an epoch value back to a time
6687         stamp:
6688        </para>
6689 <screen>
6690 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second';
6691 </screen>
6692        <para>
6693         (The <function>to_timestamp</> function encapsulates the above
6694         conversion.)
6695        </para>
6696       </listitem>
6697      </varlistentry>
6698
6699      <varlistentry>
6700       <term><literal>hour</literal></term>
6701       <listitem>
6702        <para>
6703         The hour field (0 - 23)
6704        </para>
6705
6706 <screen>
6707 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6708 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6709 </screen>
6710       </listitem>
6711      </varlistentry>
6712
6713      <varlistentry>
6714       <term><literal>isodow</literal></term>
6715       <listitem>
6716        <para>
6717         The day of the week as Monday(<literal>1</>) to
6718         Sunday(<literal>7</>)
6719        </para>
6720
6721 <screen>
6722 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6723 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6724 </screen>
6725        <para>
6726         This is identical to <literal>dow</> except for Sunday.  This
6727         matches the <acronym>ISO</> 8601 day of the week numbering.
6728        </para>
6729
6730       </listitem>
6731      </varlistentry>
6732
6733      <varlistentry>
6734       <term><literal>isoyear</literal></term>
6735       <listitem>
6736        <para>
6737         The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals)
6738        </para>
6739
6740 <screen>
6741 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6742 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6743 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6744 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6745 </screen>
6746
6747        <para>
6748         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.
6749        </para>
6750        <para>
6751         This field is not available in PostgreSQL releases prior to 8.3.
6752        </para>
6753       </listitem>
6754      </varlistentry>
6755
6756      <varlistentry>
6757       <term><literal>microseconds</literal></term>
6758       <listitem>
6759        <para>
6760         The seconds field, including fractional parts, multiplied by 1
6761         000 000;  note that this includes full seconds
6762        </para>
6763
6764 <screen>
6765 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6766 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6767 </screen>
6768       </listitem>
6769      </varlistentry>
6770
6771      <varlistentry>
6772       <term><literal>millennium</literal></term>
6773       <listitem>
6774        <para>
6775         The millennium
6776        </para>
6777
6778 <screen>
6779 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6780 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6781 </screen>
6782
6783        <para>
6784         Years in the 1900s are in the second millennium.
6785         The third millennium started January 1, 2001.
6786        </para>
6787
6788        <para>
6789         <productname>PostgreSQL</productname> releases before 8.0 did not
6790         follow the conventional numbering of millennia, but just returned
6791         the year field divided by 1000.
6792        </para>
6793       </listitem>
6794      </varlistentry>
6795
6796      <varlistentry>
6797       <term><literal>milliseconds</literal></term>
6798       <listitem>
6799        <para>
6800         The seconds field, including fractional parts, multiplied by
6801         1000.  Note that this includes full seconds.
6802        </para>
6803
6804 <screen>
6805 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6806 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6807 </screen>
6808       </listitem>
6809      </varlistentry>
6810
6811      <varlistentry>
6812       <term><literal>minute</literal></term>
6813       <listitem>
6814        <para>
6815         The minutes field (0 - 59)
6816        </para>
6817
6818 <screen>
6819 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6820 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6821 </screen>
6822       </listitem>
6823      </varlistentry>
6824
6825      <varlistentry>
6826       <term><literal>month</literal></term>
6827       <listitem>
6828        <para>
6829         For <type>timestamp</type> values, the number of the month
6830         within the year (1 - 12) ; for <type>interval</type> values
6831         the number of months, modulo 12 (0 - 11)
6832        </para>
6833
6834 <screen>
6835 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6836 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6837
6838 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6839 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6840
6841 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6842 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6843 </screen>
6844       </listitem>
6845      </varlistentry>
6846
6847      <varlistentry>
6848       <term><literal>quarter</literal></term>
6849       <listitem>
6850        <para>
6851         The quarter of the year (1 - 4) that the date is in
6852        </para>
6853
6854 <screen>
6855 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6856 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6857 </screen>
6858       </listitem>
6859      </varlistentry>
6860
6861      <varlistentry>
6862       <term><literal>second</literal></term>
6863       <listitem>
6864        <para>
6865         The seconds field, including fractional parts (0 -
6866         59<footnote><simpara>60 if leap seconds are
6867         implemented by the operating system</simpara></footnote>)
6868        </para>
6869
6870 <screen>
6871 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6872 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6873
6874 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6875 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6876 </screen>
6877       </listitem>
6878      </varlistentry>
6879      <varlistentry>
6880       <term><literal>timezone</literal></term>
6881       <listitem>
6882        <para>
6883         The time zone offset from UTC, measured in seconds.  Positive values
6884         correspond to time zones east of UTC, negative values to
6885         zones west of UTC.
6886        </para>
6887       </listitem>
6888      </varlistentry>
6889
6890      <varlistentry>
6891       <term><literal>timezone_hour</literal></term>
6892       <listitem>
6893        <para>
6894         The hour component of the time zone offset
6895        </para>
6896       </listitem>
6897      </varlistentry>
6898
6899      <varlistentry>
6900       <term><literal>timezone_minute</literal></term>
6901       <listitem>
6902        <para>
6903         The minute component of the time zone offset
6904        </para>
6905       </listitem>
6906      </varlistentry>
6907
6908      <varlistentry>
6909       <term><literal>week</literal></term>
6910       <listitem>
6911        <para>
6912         The number of the week of the year that the day is in.  By definition
6913         (<acronym>ISO</acronym> 8601), the first week of a year
6914         contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
6915         week starts on Monday.)  In other words, the first Thursday of
6916         a year is in week 1 of that year.
6917        </para>
6918        <para>
6919         Because of this, it is possible for early January dates to be part of the
6920         52nd or 53rd week of the previous year.  For example, <literal>2005-01-01</>
6921         is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of
6922         the 52nd week of year 2005.
6923        </para>
6924
6925 <screen>
6926 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6927 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6928 </screen>
6929       </listitem>
6930      </varlistentry>
6931
6932      <varlistentry>
6933       <term><literal>year</literal></term>
6934       <listitem>
6935        <para>
6936         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting
6937         <literal>BC</> years from <literal>AD</> years should be done with care.
6938        </para>
6939
6940 <screen>
6941 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6942 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6943 </screen>
6944       </listitem>
6945      </varlistentry>
6946
6947     </variablelist>
6948    </para>
6949
6950    <para>
6951     The <function>extract</function> function is primarily intended
6952     for computational processing.  For formatting date/time values for
6953     display, see <xref linkend="functions-formatting">.
6954    </para>
6955
6956    <para>
6957     The <function>date_part</function> function is modeled on the traditional
6958     <productname>Ingres</productname> equivalent to the
6959     <acronym>SQL</acronym>-standard function <function>extract</function>:
6960 <synopsis>
6961 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6962 </synopsis>
6963     Note that here the <replaceable>field</replaceable> parameter needs to
6964     be a string value, not a name.  The valid field names for
6965     <function>date_part</function> are the same as for
6966     <function>extract</function>.
6967    </para>
6968
6969 <screen>
6970 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
6971 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6972
6973 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
6974 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
6975 </screen>
6976
6977   </sect2>
6978
6979   <sect2 id="functions-datetime-trunc">
6980    <title><function>date_trunc</function></title>
6981
6982    <indexterm>
6983     <primary>date_trunc</primary>
6984    </indexterm>
6985
6986    <para>
6987     The function <function>date_trunc</function> is conceptually
6988     similar to the <function>trunc</function> function for numbers.
6989    </para>
6990
6991    <para>
6992 <synopsis>
6993 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6994 </synopsis>
6995     <replaceable>source</replaceable> is a value expression of type
6996     <type>timestamp</type> or <type>interval</>.
6997     (Values of type <type>date</type> and
6998     <type>time</type> are cast automatically to <type>timestamp</type> or
6999     <type>interval</>, respectively.)
7000     <replaceable>field</replaceable> selects to which precision to
7001     truncate the input value.  The return value is of type
7002     <type>timestamp</type> or <type>interval</>
7003     with all fields that are less significant than the
7004     selected one set to zero (or one, for day and month).
7005    </para>
7006
7007    <para>
7008     Valid values for <replaceable>field</replaceable> are:
7009     <simplelist>
7010      <member><literal>microseconds</literal></member>
7011      <member><literal>milliseconds</literal></member>
7012      <member><literal>second</literal></member>
7013      <member><literal>minute</literal></member>
7014      <member><literal>hour</literal></member>
7015      <member><literal>day</literal></member>
7016      <member><literal>week</literal></member>
7017      <member><literal>month</literal></member>
7018      <member><literal>quarter</literal></member>
7019      <member><literal>year</literal></member>
7020      <member><literal>decade</literal></member>
7021      <member><literal>century</literal></member>
7022      <member><literal>millennium</literal></member>
7023     </simplelist>
7024    </para>
7025
7026    <para>
7027     Examples:
7028 <screen>
7029 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
7030 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
7031
7032 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
7033 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
7034 </screen>
7035    </para>
7036   </sect2>
7037
7038   <sect2 id="functions-datetime-zoneconvert">
7039    <title><literal>AT TIME ZONE</literal></title>
7040
7041    <indexterm>
7042     <primary>time zone</primary>
7043     <secondary>conversion</secondary>
7044    </indexterm>
7045
7046    <indexterm>
7047     <primary>AT TIME ZONE</primary>
7048    </indexterm>
7049
7050    <para>
7051     The <literal>AT TIME ZONE</literal> construct allows conversions
7052     of time stamps to different time zones.  <xref
7053     linkend="functions-datetime-zoneconvert-table"> shows its
7054     variants.
7055    </para>
7056
7057     <table id="functions-datetime-zoneconvert-table">
7058      <title><literal>AT TIME ZONE</literal> Variants</title>
7059      <tgroup cols="3">
7060       <thead>
7061        <row>
7062         <entry>Expression</entry>
7063         <entry>Return Type</entry>
7064         <entry>Description</entry>
7065        </row>
7066       </thead>
7067
7068       <tbody>
7069        <row>
7070         <entry>
7071          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7072         </entry>
7073         <entry><type>timestamp with time zone</type></entry>
7074         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
7075        </row>
7076
7077        <row>
7078         <entry>
7079          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7080         </entry>
7081         <entry><type>timestamp without time zone</type></entry>
7082         <entry>Convert given time stamp <emphasis>with time zone</> to the new time
7083         zone, with no time zone designation</entry>
7084        </row>
7085
7086        <row>
7087         <entry>
7088          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7089         </entry>
7090         <entry><type>time with time zone</type></entry>
7091         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
7092        </row>
7093       </tbody>
7094      </tgroup>
7095     </table>
7096
7097    <para>
7098     In these expressions, the desired time zone <replaceable>zone</> can be
7099     specified either as a text string (e.g., <literal>'PST'</literal>)
7100     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
7101     In the text case, a time zone name can be specified in any of the ways
7102     described in <xref linkend="datatype-timezones">.
7103    </para>
7104
7105    <para>
7106     Examples (assuming the local time zone is <literal>PST8PDT</>):
7107 <screen>
7108 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
7109 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
7110
7111 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
7112 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
7113 </screen>
7114     The first example takes a time stamp without time zone and interprets it as MST time
7115     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes
7116     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
7117    </para>
7118
7119    <para>
7120     The function <literal><function>timezone</function>(<replaceable>zone</>,
7121     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
7122     <literal><replaceable>timestamp</> AT TIME ZONE
7123     <replaceable>zone</></literal>.
7124    </para>
7125   </sect2>
7126
7127   <sect2 id="functions-datetime-current">
7128    <title>Current Date/Time</title>
7129
7130    <indexterm>
7131     <primary>date</primary>
7132     <secondary>current</secondary>
7133    </indexterm>
7134
7135    <indexterm>
7136     <primary>time</primary>
7137     <secondary>current</secondary>
7138    </indexterm>
7139
7140    <para>
7141     <productname>PostgreSQL</productname> provides a number of functions
7142     that return values related to the current date and time.  These
7143     SQL-standard functions all return values based on the start time of
7144     the current transaction:
7145 <synopsis>
7146 CURRENT_DATE
7147 CURRENT_TIME
7148 CURRENT_TIMESTAMP
7149 CURRENT_TIME(<replaceable>precision</replaceable>)
7150 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
7151 LOCALTIME
7152 LOCALTIMESTAMP
7153 LOCALTIME(<replaceable>precision</replaceable>)
7154 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
7155 </synopsis>
7156     </para>
7157
7158     <para>
7159      <function>CURRENT_TIME</function> and
7160      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
7161      <function>LOCALTIME</function> and
7162      <function>LOCALTIMESTAMP</function> deliver values without time zone.
7163     </para>
7164
7165     <para>
7166      <function>CURRENT_TIME</function>,
7167      <function>CURRENT_TIMESTAMP</function>,
7168      <function>LOCALTIME</function>, and
7169      <function>LOCALTIMESTAMP</function>
7170      can optionally take
7171      a precision parameter, which causes the result to be rounded
7172      to that many fractional digits in the seconds field.  Without a precision parameter,
7173      the result is given to the full available precision.
7174     </para>
7175
7176    <para>
7177     Some examples:
7178 <screen>
7179 SELECT CURRENT_TIME;
7180 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
7181
7182 SELECT CURRENT_DATE;
7183 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
7184
7185 SELECT CURRENT_TIMESTAMP;
7186 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
7187
7188 SELECT CURRENT_TIMESTAMP(2);
7189 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
7190
7191 SELECT LOCALTIMESTAMP;
7192 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
7193 </screen>
7194    </para>
7195
7196    <para>
7197     Since these functions return
7198     the start time of the current transaction, their values do not
7199     change during the transaction. This is considered a feature:
7200     the intent is to allow a single transaction to have a consistent
7201     notion of the <quote>current</quote> time, so that multiple
7202     modifications within the same transaction bear the same
7203     time stamp.
7204    </para>
7205
7206    <note>
7207     <para>
7208      Other database systems might advance these values more
7209      frequently.
7210     </para>
7211    </note>
7212
7213    <para>
7214     <productname>PostgreSQL</productname> also provides functions that
7215     return the start time of the current statement, as well as the actual
7216     current time at the instant the function is called.  The complete list
7217     of non-SQL-standard time functions is:
7218 <synopsis>
7219 transaction_timestamp()
7220 statement_timestamp()
7221 clock_timestamp()
7222 timeofday()
7223 now()
7224 </synopsis>
7225    </para>
7226
7227    <para>
7228     <function>transaction_timestamp()</> is equivalent to
7229     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
7230     what it returns.
7231     <function>statement_timestamp()</> returns the start time of the current
7232     statement (more specifically, the time of receipt of the latest command
7233     message from the client).
7234     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
7235     return the same value during the first command of a transaction, but might
7236     differ during subsequent commands.
7237     <function>clock_timestamp()</> returns the actual current time, and
7238     therefore its value changes even within a single SQL command.
7239     <function>timeofday()</> is a historical
7240     <productname>PostgreSQL</productname> function.  Like
7241     <function>clock_timestamp()</>, it returns the actual current time,
7242     but as a formatted <type>text</> string rather than a <type>timestamp
7243     with time zone</> value.
7244     <function>now()</> is a traditional <productname>PostgreSQL</productname>
7245     equivalent to <function>transaction_timestamp()</function>.
7246    </para>
7247
7248    <para>
7249     All the date/time data types also accept the special literal value
7250     <literal>now</literal> to specify the current date and time (again,
7251     interpreted as the transaction start time).  Thus,
7252     the following three all return the same result:
7253 <programlisting>
7254 SELECT CURRENT_TIMESTAMP;
7255 SELECT now();
7256 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
7257 </programlisting>
7258    </para>
7259
7260     <tip>
7261      <para>
7262       You do not want to use the third form when specifying a <literal>DEFAULT</>
7263       clause while creating a table.  The system will convert <literal>now</literal>
7264       to a <type>timestamp</type> as soon as the constant is parsed, so that when
7265       the default value is needed,
7266       the time of the table creation would be used!  The first two
7267       forms will not be evaluated until the default value is used,
7268       because they are function calls.  Thus they will give the desired
7269       behavior of defaulting to the time of row insertion.
7270      </para>
7271     </tip>
7272   </sect2>
7273
7274   <sect2 id="functions-datetime-delay">
7275    <title>Delaying Execution</title>
7276
7277    <indexterm>
7278     <primary>pg_sleep</primary>
7279    </indexterm>
7280    <indexterm>
7281     <primary>sleep</primary>
7282    </indexterm>
7283    <indexterm>
7284     <primary>delay</primary>
7285    </indexterm>
7286
7287    <para>
7288     The following function is available to delay execution of the server
7289     process:
7290 <synopsis>
7291 pg_sleep(<replaceable>seconds</replaceable>)
7292 </synopsis>
7293
7294     <function>pg_sleep</function> makes the current session's process
7295     sleep until <replaceable>seconds</replaceable> seconds have
7296     elapsed.  <replaceable>seconds</replaceable> is a value of type
7297     <type>double precision</>, so fractional-second delays can be specified.
7298     For example:
7299
7300 <programlisting>
7301 SELECT pg_sleep(1.5);
7302 </programlisting>
7303    </para>
7304
7305    <note>
7306      <para>
7307       The effective resolution of the sleep interval is platform-specific;
7308       0.01 seconds is a common value.  The sleep delay will be at least as long
7309       as specified. It might be longer depending on factors such as server load.
7310      </para>
7311    </note>
7312
7313    <warning>
7314      <para>
7315       Make sure that your session does not hold more locks than necessary
7316       when calling <function>pg_sleep</function>.  Otherwise other sessions
7317       might have to wait for your sleeping process, slowing down the entire
7318       system.
7319      </para>
7320    </warning>
7321   </sect2>
7322
7323  </sect1>
7324
7325
7326  <sect1 id="functions-enum">
7327   <title>Enum Support Functions</title>
7328
7329   <para>
7330    For enum types (described in <xref linkend="datatype-enum">),
7331    there are several functions that allow cleaner programming without
7332    hard-coding particular values of an enum type.
7333    These are listed in <xref linkend="functions-enum-table">. The examples
7334    assume an enum type created as:
7335
7336 <programlisting>
7337 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
7338 </programlisting>
7339
7340   </para>
7341
7342   <table id="functions-enum-table">
7343     <title>Enum Support Functions</title>
7344     <tgroup cols="4">
7345      <thead>
7346       <row>
7347        <entry>Function</entry>
7348        <entry>Description</entry>
7349        <entry>Example</entry>
7350        <entry>Example Result</entry>
7351       </row>
7352      </thead>
7353      <tbody>
7354       <row>
7355        <entry>
7356          <indexterm>
7357           <primary>enum_first</primary>
7358          </indexterm>
7359          <literal>enum_first(anyenum)</literal>
7360        </entry>
7361        <entry>Returns the first value of the input enum type</entry>
7362        <entry><literal>enum_first(null::rainbow)</literal></entry>
7363        <entry><literal>red</literal></entry>
7364       </row>
7365       <row>
7366        <entry>
7367          <indexterm>
7368           <primary>enum_last</primary>
7369          </indexterm>
7370          <literal>enum_last(anyenum)</literal>
7371        </entry>
7372        <entry>Returns the last value of the input enum type</entry>
7373        <entry><literal>enum_last(null::rainbow)</literal></entry>
7374        <entry><literal>purple</literal></entry>
7375       </row>
7376       <row>
7377        <entry>
7378          <indexterm>
7379           <primary>enum_range</primary>
7380          </indexterm>
7381          <literal>enum_range(anyenum)</literal>
7382        </entry>
7383        <entry>Returns all values of the input enum type in an ordered array</entry>
7384        <entry><literal>enum_range(null::rainbow)</literal></entry>
7385        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
7386       </row>
7387       <row>
7388        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
7389        <entry morerows="2">
7390         Returns the range between the two given enum values, as an ordered
7391         array. The values must be from the same enum type. If the first
7392         parameter is null, the result will start with the first value of
7393         the enum type.
7394         If the second parameter is null, the result will end with the last
7395         value of the enum type.
7396        </entry>
7397        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
7398        <entry><literal>{orange,yellow,green}</literal></entry>
7399       </row>
7400       <row>
7401        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
7402        <entry><literal>{red,orange,yellow,green}</literal></entry>
7403       </row>
7404       <row>
7405        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
7406        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
7407       </row>
7408      </tbody>
7409     </tgroup>
7410    </table>
7411
7412    <para>
7413     Notice that except for the two-argument form of <function>enum_range</>,
7414     these functions disregard the specific value passed to them; they care
7415     only about its declared data type.  Either null or a specific value of
7416     the type can be passed, with the same result.  It is more common to
7417     apply these functions to a table column or function argument than to
7418     a hardwired type name as suggested by the examples.
7419    </para>
7420  </sect1>
7421
7422  <sect1 id="functions-geometry">
7423   <title>Geometric Functions and Operators</title>
7424
7425    <para>
7426     The geometric types <type>point</type>, <type>box</type>,
7427     <type>lseg</type>, <type>line</type>, <type>path</type>,
7428     <type>polygon</type>, and <type>circle</type> have a large set of
7429     native support functions and operators, shown in <xref
7430     linkend="functions-geometry-op-table">, <xref
7431     linkend="functions-geometry-func-table">, and <xref
7432     linkend="functions-geometry-conv-table">.
7433    </para>
7434
7435    <caution>
7436     <para>
7437      Note that the <quote>same as</> operator, <literal>~=</>, represents
7438      the usual notion of equality for the <type>point</type>,
7439      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
7440      Some of these types also have an <literal>=</> operator, but
7441      <literal>=</> compares
7442      for equal <emphasis>areas</> only.  The other scalar comparison operators
7443      (<literal>&lt;=</> and so on) likewise compare areas for these types.
7444     </para>
7445    </caution>
7446
7447    <table id="functions-geometry-op-table">
7448      <title>Geometric Operators</title>
7449      <tgroup cols="3">
7450       <thead>
7451        <row>
7452         <entry>Operator</entry>
7453         <entry>Description</entry>
7454         <entry>Example</entry>
7455        </row>
7456       </thead>
7457       <tbody>
7458        <row>
7459         <entry> <literal>+</literal> </entry>
7460         <entry>Translation</entry>
7461         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
7462        </row>
7463        <row>
7464         <entry> <literal>-</literal> </entry>
7465         <entry>Translation</entry>
7466         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
7467        </row>
7468        <row>
7469         <entry> <literal>*</literal> </entry>
7470         <entry>Scaling/rotation</entry>
7471         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
7472        </row>
7473        <row>
7474         <entry> <literal>/</literal> </entry>
7475         <entry>Scaling/rotation</entry>
7476         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
7477        </row>
7478        <row>
7479         <entry> <literal>#</literal> </entry>
7480         <entry>Point or box of intersection</entry>
7481         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
7482        </row>
7483        <row>
7484         <entry> <literal>#</literal> </entry>
7485         <entry>Number of points in path or polygon</entry>
7486         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
7487        </row>
7488        <row>
7489         <entry> <literal>@-@</literal> </entry>
7490         <entry>Length or circumference</entry>
7491         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
7492        </row>
7493        <row>
7494         <entry> <literal>@@</literal> </entry>
7495         <entry>Center</entry>
7496         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
7497        </row>
7498        <row>
7499         <entry> <literal>##</literal> </entry>
7500         <entry>Closest point to first operand on second operand</entry>
7501         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
7502        </row>
7503        <row>
7504         <entry> <literal>&lt;-&gt;</literal> </entry>
7505         <entry>Distance between</entry>
7506         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
7507        </row>
7508        <row>
7509         <entry> <literal>&amp;&amp;</literal> </entry>
7510         <entry>Overlaps?  (One point in common makes this true.)</entry>
7511         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
7512        </row>
7513        <row>
7514         <entry> <literal>&lt;&lt;</literal> </entry>
7515         <entry>Is strictly left of?</entry>
7516         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
7517        </row>
7518        <row>
7519         <entry> <literal>&gt;&gt;</literal> </entry>
7520         <entry>Is strictly right of?</entry>
7521         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
7522        </row>
7523        <row>
7524         <entry> <literal>&amp;&lt;</literal> </entry>
7525         <entry>Does not extend to the right of?</entry>
7526         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
7527        </row>
7528        <row>
7529         <entry> <literal>&amp;&gt;</literal> </entry>
7530         <entry>Does not extend to the left of?</entry>
7531         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
7532        </row>
7533        <row>
7534         <entry> <literal>&lt;&lt;|</literal> </entry>
7535         <entry>Is strictly below?</entry>
7536         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
7537        </row>
7538        <row>
7539         <entry> <literal>|&gt;&gt;</literal> </entry>
7540         <entry>Is strictly above?</entry>
7541         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
7542        </row>
7543        <row>
7544         <entry> <literal>&amp;&lt;|</literal> </entry>
7545         <entry>Does not extend above?</entry>
7546         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
7547        </row>
7548        <row>
7549         <entry> <literal>|&amp;&gt;</literal> </entry>
7550         <entry>Does not extend below?</entry>
7551         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
7552        </row>
7553        <row>
7554         <entry> <literal>&lt;^</literal> </entry>
7555         <entry>Is below (allows touching)?</entry>
7556         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
7557        </row>
7558        <row>
7559         <entry> <literal>&gt;^</literal> </entry>
7560         <entry>Is above (allows touching)?</entry>
7561         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
7562        </row>
7563        <row>
7564         <entry> <literal>?#</literal> </entry>
7565         <entry>Intersects?</entry>
7566         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7567        </row>
7568        <row>
7569         <entry> <literal>?-</literal> </entry>
7570         <entry>Is horizontal?</entry>
7571         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7572        </row>
7573        <row>
7574         <entry> <literal>?-</literal> </entry>
7575         <entry>Are horizontally aligned?</entry>
7576         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7577        </row>
7578        <row>
7579         <entry> <literal>?|</literal> </entry>
7580         <entry>Is vertical?</entry>
7581         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7582        </row>
7583        <row>
7584         <entry> <literal>?|</literal> </entry>
7585         <entry>Are vertically aligned?</entry>
7586         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7587        </row>
7588        <row>
7589         <entry> <literal>?-|</literal> </entry>
7590         <entry>Is perpendicular?</entry>
7591         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7592        </row>
7593        <row>
7594         <entry> <literal>?||</literal> </entry>
7595         <entry>Are parallel?</entry>
7596         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7597        </row>
7598        <row>
7599         <entry> <literal>@&gt;</literal> </entry>
7600         <entry>Contains?</entry>
7601         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7602        </row>
7603        <row>
7604         <entry> <literal>&lt;@</literal> </entry>
7605         <entry>Contained in or on?</entry>
7606         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7607        </row>
7608        <row>
7609         <entry> <literal>~=</literal> </entry>
7610         <entry>Same as?</entry>
7611         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7612        </row>
7613       </tbody>
7614      </tgroup>
7615    </table>
7616
7617    <note>
7618     <para>
7619      Before <productname>PostgreSQL</productname> 8.2, the containment
7620      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7621      called <literal>~</> and <literal>@</>.  These names are still
7622      available, but are deprecated and will eventually be removed.
7623     </para>
7624    </note>
7625
7626    <indexterm>
7627     <primary>area</primary>
7628    </indexterm>
7629    <indexterm>
7630     <primary>center</primary>
7631    </indexterm>
7632    <indexterm>
7633     <primary>diameter</primary>
7634    </indexterm>
7635    <indexterm>
7636     <primary>height</primary>
7637    </indexterm>
7638    <indexterm>
7639     <primary>isclosed</primary>
7640    </indexterm>
7641    <indexterm>
7642     <primary>isopen</primary>
7643    </indexterm>
7644    <indexterm>
7645     <primary>length</primary>
7646    </indexterm>
7647    <indexterm>
7648     <primary>npoints</primary>
7649    </indexterm>
7650    <indexterm>
7651     <primary>pclose</primary>
7652    </indexterm>
7653    <indexterm>
7654     <primary>popen</primary>
7655    </indexterm>
7656    <indexterm>
7657     <primary>radius</primary>
7658    </indexterm>
7659    <indexterm>
7660     <primary>width</primary>
7661    </indexterm>
7662
7663    <table id="functions-geometry-func-table">
7664      <title>Geometric Functions</title>
7665      <tgroup cols="4">
7666       <thead>
7667        <row>
7668         <entry>Function</entry>
7669         <entry>Return Type</entry>
7670         <entry>Description</entry>
7671         <entry>Example</entry>
7672        </row>
7673       </thead>
7674       <tbody>
7675        <row>
7676         <entry><literal><function>area(<replaceable>object</>)</function></literal></entry>
7677         <entry><type>double precision</type></entry>
7678         <entry>area</entry>
7679         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7680        </row>
7681        <row>
7682         <entry><literal><function>center(<replaceable>object</>)</function></literal></entry>
7683         <entry><type>point</type></entry>
7684         <entry>center</entry>
7685         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7686        </row>
7687        <row>
7688         <entry><literal><function>diameter(<type>circle</>)</function></literal></entry>
7689         <entry><type>double precision</type></entry>
7690         <entry>diameter of circle</entry>
7691         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7692        </row>
7693        <row>
7694         <entry><literal><function>height(<type>box</>)</function></literal></entry>
7695         <entry><type>double precision</type></entry>
7696         <entry>vertical size of box</entry>
7697         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7698        </row>
7699        <row>
7700         <entry><literal><function>isclosed(<type>path</>)</function></literal></entry>
7701         <entry><type>boolean</type></entry>
7702         <entry>a closed path?</entry>
7703         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7704        </row>
7705        <row>
7706         <entry><literal><function>isopen(<type>path</>)</function></literal></entry>
7707         <entry><type>boolean</type></entry>
7708         <entry>an open path?</entry>
7709         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7710        </row>
7711        <row>
7712         <entry><literal><function>length(<replaceable>object</>)</function></literal></entry>
7713         <entry><type>double precision</type></entry>
7714         <entry>length</entry>
7715         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7716        </row>
7717        <row>
7718         <entry><literal><function>npoints(<type>path</>)</function></literal></entry>
7719         <entry><type>int</type></entry>
7720         <entry>number of points</entry>
7721         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7722        </row>
7723        <row>
7724         <entry><literal><function>npoints(<type>polygon</>)</function></literal></entry>
7725         <entry><type>int</type></entry>
7726         <entry>number of points</entry>
7727         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7728        </row>
7729        <row>
7730         <entry><literal><function>pclose(<type>path</>)</function></literal></entry>
7731         <entry><type>path</type></entry>
7732         <entry>convert path to closed</entry>
7733         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7734        </row>
7735 <![IGNORE[
7736 <!-- Not defined by this name. Implements the intersection operator '#' -->
7737        <row>
7738         <entry><literal><function>point(<type>lseg</>, <type>lseg</>)</function></literal></entry>
7739         <entry><type>point</type></entry>
7740         <entry>intersection</entry>
7741         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7742        </row>
7743 ]]>
7744        <row>
7745         <entry><literal><function>popen(<type>path</>)</function></literal></entry>
7746         <entry><type>path</type></entry>
7747         <entry>convert path to open</entry>
7748         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7749        </row>
7750        <row>
7751         <entry><literal><function>radius(<type>circle</type>)</function></literal></entry>
7752         <entry><type>double precision</type></entry>
7753         <entry>radius of circle</entry>
7754         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7755        </row>
7756        <row>
7757         <entry><literal><function>width(<type>box</>)</function></literal></entry>
7758         <entry><type>double precision</type></entry>
7759         <entry>horizontal size of box</entry>
7760         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7761        </row>
7762       </tbody>
7763      </tgroup>
7764    </table>
7765
7766    <table id="functions-geometry-conv-table">
7767      <title>Geometric Type Conversion Functions</title>
7768      <tgroup cols="4">
7769       <thead>
7770        <row>
7771         <entry>Function</entry>
7772         <entry>Return Type</entry>
7773         <entry>Description</entry>
7774         <entry>Example</entry>
7775        </row>
7776       </thead>
7777       <tbody>
7778        <row>
7779         <entry>
7780          <indexterm>
7781           <primary>box</primary>
7782          </indexterm>
7783          <literal><function>box(<type>circle</type>)</function></literal>
7784         </entry>
7785         <entry><type>box</type></entry>
7786         <entry>circle to box</entry>
7787         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7788        </row>
7789        <row>
7790         <entry><literal><function>box(<type>point</type>, <type>point</type>)</function></literal></entry>
7791         <entry><type>box</type></entry>
7792         <entry>points to box</entry>
7793         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7794        </row>
7795        <row>
7796         <entry><literal><function>box(<type>polygon</type>)</function></literal></entry>
7797         <entry><type>box</type></entry>
7798         <entry>polygon to box</entry>
7799         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7800        </row>
7801        <row>
7802         <entry>
7803          <indexterm>
7804           <primary>circle</primary>
7805          </indexterm>
7806          <literal><function>circle(<type>box</type>)</function></literal>
7807         </entry>
7808         <entry><type>circle</type></entry>
7809         <entry>box to circle</entry>
7810         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7811        </row>
7812        <row>
7813         <entry><literal><function>circle(<type>point</type>, <type>double precision</type>)</function></literal></entry>
7814         <entry><type>circle</type></entry>
7815         <entry>center and radius to circle</entry>
7816         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7817        </row>
7818        <row>
7819         <entry><literal><function>circle(<type>polygon</type>)</function></literal></entry>
7820         <entry><type>circle</type></entry>
7821         <entry>polygon to circle</entry>
7822         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7823        </row>
7824        <row>
7825         <entry>
7826          <indexterm>
7827           <primary>lseg</primary>
7828          </indexterm>
7829          <literal><function>lseg(<type>box</type>)</function></literal>
7830         </entry>
7831         <entry><type>lseg</type></entry>
7832         <entry>box diagonal to line segment</entry>
7833         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7834        </row>
7835        <row>
7836         <entry><literal><function>lseg(<type>point</type>, <type>point</type>)</function></literal></entry>
7837         <entry><type>lseg</type></entry>
7838         <entry>points to line segment</entry>
7839         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7840        </row>
7841        <row>
7842         <entry>
7843          <indexterm>
7844           <primary>path</primary>
7845          </indexterm>
7846          <literal><function>path(<type>polygon</type>)</function></literal>
7847         </entry>
7848         <entry><type>point</type></entry>
7849         <entry>polygon to path</entry>
7850         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7851        </row>
7852        <row>
7853         <entry>
7854          <indexterm>
7855           <primary>point</primary>
7856          </indexterm>
7857          <literal><function>point</function>(<type>double
7858          precision</type>, <type>double precision</type>)</literal>
7859         </entry>
7860         <entry><type>point</type></entry>
7861         <entry>construct point</entry>
7862         <entry><literal>point(23.4, -44.5)</literal></entry>
7863        </row>
7864        <row>
7865         <entry><literal><function>point(<type>box</type>)</function></literal></entry>
7866         <entry><type>point</type></entry>
7867         <entry>center of box</entry>
7868         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7869        </row>
7870        <row>
7871         <entry><literal><function>point(<type>circle</type>)</function></literal></entry>
7872         <entry><type>point</type></entry>
7873         <entry>center of circle</entry>
7874         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7875        </row>
7876        <row>
7877         <entry><literal><function>point(<type>lseg</type>)</function></literal></entry>
7878         <entry><type>point</type></entry>
7879         <entry>center of line segment</entry>
7880         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7881        </row>
7882        <row>
7883         <entry><literal><function>point(<type>polygon</type>)</function></literal></entry>
7884         <entry><type>point</type></entry>
7885         <entry>center of polygon</entry>
7886         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7887        </row>
7888        <row>
7889         <entry>
7890          <indexterm>
7891           <primary>polygon</primary>
7892          </indexterm>
7893          <literal><function>polygon(<type>box</type>)</function></literal>
7894         </entry>
7895         <entry><type>polygon</type></entry>
7896         <entry>box to 4-point polygon</entry>
7897         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7898        </row>
7899        <row>
7900         <entry><literal><function>polygon(<type>circle</type>)</function></literal></entry>
7901         <entry><type>polygon</type></entry>
7902         <entry>circle to 12-point polygon</entry>
7903         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7904        </row>
7905        <row>
7906         <entry><literal><function>polygon(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</function></literal></entry>
7907         <entry><type>polygon</type></entry>
7908         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
7909         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7910        </row>
7911        <row>
7912         <entry><literal><function>polygon(<type>path</type>)</function></literal></entry>
7913         <entry><type>polygon</type></entry>
7914         <entry>path to polygon</entry>
7915         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7916        </row>
7917       </tbody>
7918      </tgroup>
7919    </table>
7920
7921     <para>
7922      It is possible to access the two component numbers of a <type>point</>
7923      as though the point were an array with indexes 0 and 1.  For example, if
7924      <literal>t.p</> is a <type>point</> column then
7925      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7926      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7927      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7928      as an array of two <type>point</> values.
7929     </para>
7930
7931     <para>
7932      The <function>area</function> function works for the types
7933      <type>box</type>, <type>circle</type>, and <type>path</type>.
7934      The <function>area</function> function only works on the
7935      <type>path</type> data type if the points in the
7936      <type>path</type> are non-intersecting.  For example, the
7937      <type>path</type>
7938      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7939      will not work;  however, the following visually identical
7940      <type>path</type>
7941      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7942      will work.  If the concept of an intersecting versus
7943      non-intersecting <type>path</type> is confusing, draw both of the
7944      above <type>path</type>s side by side on a piece of graph paper.
7945     </para>
7946
7947   </sect1>
7948
7949
7950  <sect1 id="functions-net">
7951   <title>Network Address Functions and Operators</title>
7952
7953   <para>
7954    <xref linkend="cidr-inet-operators-table"> shows the operators
7955    available for the <type>cidr</type> and <type>inet</type> types.
7956    The operators <literal>&lt;&lt;</literal>,
7957    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
7958    <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
7959    consider only the network parts of the two addresses (ignoring any
7960    host part) and determine whether one network is identical to
7961    or a subnet of the other.
7962   </para>
7963
7964     <table id="cidr-inet-operators-table">
7965      <title><type>cidr</type> and <type>inet</type> Operators</title>
7966      <tgroup cols="3">
7967       <thead>
7968        <row>
7969         <entry>Operator</entry>
7970         <entry>Description</entry>
7971         <entry>Example</entry>
7972        </row>
7973       </thead>
7974       <tbody>
7975        <row>
7976         <entry> <literal>&lt;</literal> </entry>
7977         <entry>is less than</entry>
7978         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
7979        </row>
7980        <row>
7981         <entry> <literal>&lt;=</literal> </entry>
7982         <entry>is less than or equal</entry>
7983         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
7984        </row>
7985        <row>
7986         <entry> <literal>=</literal> </entry>
7987         <entry>equals</entry>
7988         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
7989        </row>
7990        <row>
7991         <entry> <literal>&gt;=</literal> </entry>
7992         <entry>is greater or equal</entry>
7993         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
7994        </row>
7995        <row>
7996         <entry> <literal>&gt;</literal> </entry>
7997         <entry>is greater than</entry>
7998         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
7999        </row>
8000        <row>
8001         <entry> <literal>&lt;&gt;</literal> </entry>
8002         <entry>is not equal</entry>
8003         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
8004        </row>
8005        <row>
8006         <entry> <literal>&lt;&lt;</literal> </entry>
8007         <entry>is contained within</entry>
8008         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
8009        </row>
8010        <row>
8011         <entry> <literal>&lt;&lt;=</literal> </entry>
8012         <entry>is contained within or equals</entry>
8013         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
8014        </row>
8015        <row>
8016         <entry> <literal>&gt;&gt;</literal> </entry>
8017         <entry>contains</entry>
8018         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
8019        </row>
8020        <row>
8021         <entry> <literal>&gt;&gt;=</literal> </entry>
8022         <entry>contains or equals</entry>
8023         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
8024        </row>
8025        <row>
8026         <entry> <literal>~</literal> </entry>
8027         <entry>bitwise NOT</entry>
8028         <entry><literal>~ inet '192.168.1.6'</literal></entry>
8029        </row>
8030        <row>
8031         <entry> <literal>&amp;</literal> </entry>
8032         <entry>bitwise AND</entry>
8033         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
8034        </row>
8035        <row>
8036         <entry> <literal>|</literal> </entry>
8037         <entry>bitwise OR</entry>
8038         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
8039        </row>
8040        <row>
8041         <entry> <literal>+</literal> </entry>
8042         <entry>addition</entry>
8043         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
8044        </row>
8045        <row>
8046         <entry> <literal>-</literal> </entry>
8047         <entry>subtraction</entry>
8048         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
8049        </row>
8050        <row>
8051         <entry> <literal>-</literal> </entry>
8052         <entry>subtraction</entry>
8053         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
8054        </row>
8055       </tbody>
8056      </tgroup>
8057     </table>
8058
8059   <para>
8060    <xref linkend="cidr-inet-functions-table"> shows the functions
8061    available for use with the <type>cidr</type> and <type>inet</type>
8062    types.  The <function>abbrev</function>, <function>host</function>,
8063    and <function>text</function>
8064    functions are primarily intended to offer alternative display
8065    formats.
8066   </para>
8067
8068     <table id="cidr-inet-functions-table">
8069      <title><type>cidr</type> and <type>inet</type> Functions</title>
8070      <tgroup cols="5">
8071       <thead>
8072        <row>
8073         <entry>Function</entry>
8074         <entry>Return Type</entry>
8075         <entry>Description</entry>
8076         <entry>Example</entry>
8077         <entry>Result</entry>
8078        </row>
8079       </thead>
8080       <tbody>
8081        <row>
8082         <entry>
8083          <indexterm>
8084           <primary>abbrev</primary>
8085          </indexterm>
8086          <literal><function>abbrev(<type>inet</type>)</function></literal>
8087         </entry>
8088         <entry><type>text</type></entry>
8089         <entry>abbreviated display format as text</entry>
8090         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
8091         <entry><literal>10.1.0.0/16</literal></entry>
8092        </row>
8093        <row>
8094         <entry><literal><function>abbrev(<type>cidr</type>)</function></literal></entry>
8095         <entry><type>text</type></entry>
8096         <entry>abbreviated display format as text</entry>
8097         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
8098         <entry><literal>10.1/16</literal></entry>
8099        </row>
8100        <row>
8101         <entry>
8102          <indexterm>
8103           <primary>broadcast</primary>
8104          </indexterm>
8105          <literal><function>broadcast(<type>inet</type>)</function></literal>
8106         </entry>
8107         <entry><type>inet</type></entry>
8108         <entry>broadcast address for network</entry>
8109         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
8110         <entry><literal>192.168.1.255/24</literal></entry>
8111        </row>
8112        <row>
8113         <entry>
8114          <indexterm>
8115           <primary>family</primary>
8116          </indexterm>
8117          <literal><function>family(<type>inet</type>)</function></literal>
8118         </entry>
8119         <entry><type>int</type></entry>
8120         <entry>extract family of address; <literal>4</literal> for IPv4,
8121          <literal>6</literal> for IPv6</entry>
8122         <entry><literal>family('::1')</literal></entry>
8123         <entry><literal>6</literal></entry>
8124        </row>
8125        <row>
8126         <entry>
8127          <indexterm>
8128           <primary>host</primary>
8129          </indexterm>
8130          <literal><function>host(<type>inet</type>)</function></literal>
8131         </entry>
8132         <entry><type>text</type></entry>
8133         <entry>extract IP address as text</entry>
8134         <entry><literal>host('192.168.1.5/24')</literal></entry>
8135         <entry><literal>192.168.1.5</literal></entry>
8136        </row>
8137        <row>
8138         <entry>
8139          <indexterm>
8140           <primary>hostmask</primary>
8141          </indexterm>
8142          <literal><function>hostmask(<type>inet</type>)</function></literal>
8143         </entry>
8144         <entry><type>inet</type></entry>
8145         <entry>construct host mask for network</entry>
8146         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
8147         <entry><literal>0.0.0.3</literal></entry>
8148        </row>
8149        <row>
8150         <entry>
8151          <indexterm>
8152           <primary>masklen</primary>
8153          </indexterm>
8154          <literal><function>masklen(<type>inet</type>)</function></literal>
8155         </entry>
8156         <entry><type>int</type></entry>
8157         <entry>extract netmask length</entry>
8158         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
8159         <entry><literal>24</literal></entry>
8160        </row>
8161        <row>
8162         <entry>
8163          <indexterm>
8164           <primary>netmask</primary>
8165          </indexterm>
8166          <literal><function>netmask(<type>inet</type>)</function></literal>
8167         </entry>
8168         <entry><type>inet</type></entry>
8169         <entry>construct netmask for network</entry>
8170         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
8171         <entry><literal>255.255.255.0</literal></entry>
8172        </row>
8173        <row>
8174         <entry>
8175          <indexterm>
8176           <primary>network</primary>
8177          </indexterm>
8178          <literal><function>network(<type>inet</type>)</function></literal>
8179         </entry>
8180         <entry><type>cidr</type></entry>
8181         <entry>extract network part of address</entry>
8182         <entry><literal>network('192.168.1.5/24')</literal></entry>
8183         <entry><literal>192.168.1.0/24</literal></entry>
8184        </row>
8185        <row>
8186         <entry>
8187          <indexterm>
8188           <primary>set_masklen</primary>
8189          </indexterm>
8190          <literal><function>set_masklen(<type>inet</type>, <type>int</type>)</function></literal>
8191         </entry>
8192         <entry><type>inet</type></entry>
8193         <entry>set netmask length for <type>inet</type> value</entry>
8194         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
8195         <entry><literal>192.168.1.5/16</literal></entry>
8196        </row>
8197        <row>
8198         <entry><literal><function>set_masklen(<type>cidr</type>, <type>int</type>)</function></literal></entry>
8199         <entry><type>cidr</type></entry>
8200         <entry>set netmask length for <type>cidr</type> value</entry>
8201         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
8202         <entry><literal>192.168.0.0/16</literal></entry>
8203        </row>
8204        <row>
8205         <entry>
8206          <indexterm>
8207           <primary>text</primary>
8208          </indexterm>
8209          <literal><function>text(<type>inet</type>)</function></literal>
8210         </entry>
8211         <entry><type>text</type></entry>
8212         <entry>extract IP address and netmask length as text</entry>
8213         <entry><literal>text(inet '192.168.1.5')</literal></entry>
8214         <entry><literal>192.168.1.5/32</literal></entry>
8215        </row>
8216       </tbody>
8217      </tgroup>
8218     </table>
8219
8220   <para>
8221    Any <type>cidr</> value can be cast to <type>inet</> implicitly
8222    or explicitly; therefore, the functions shown above as operating on
8223    <type>inet</> also work on <type>cidr</> values.  (Where there are
8224    separate functions for <type>inet</> and <type>cidr</>, it is because
8225    the behavior should be different for the two cases.)
8226    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
8227    When this is done, any bits to the right of the netmask are silently zeroed
8228    to create a valid <type>cidr</> value.
8229    In addition,
8230    you can cast a text value to <type>inet</> or <type>cidr</>
8231    using normal casting syntax: for example,
8232    <literal>inet(<replaceable>expression</>)</literal> or
8233    <literal><replaceable>colname</>::cidr</literal>.
8234   </para>
8235
8236   <para>
8237    <xref linkend="macaddr-functions-table"> shows the functions
8238    available for use with the <type>macaddr</type> type.  The function
8239    <literal><function>trunc(<type>macaddr</type>)</function></literal> returns a MAC
8240    address with the last 3 bytes set to zero.  This can be used to
8241    associate the remaining prefix with a manufacturer.
8242   </para>
8243
8244     <table id="macaddr-functions-table">
8245      <title><type>macaddr</type> Functions</title>
8246      <tgroup cols="5">
8247       <thead>
8248        <row>
8249         <entry>Function</entry>
8250         <entry>Return Type</entry>
8251         <entry>Description</entry>
8252         <entry>Example</entry>
8253         <entry>Result</entry>
8254        </row>
8255       </thead>
8256       <tbody>
8257        <row>
8258         <entry>
8259          <indexterm>
8260           <primary>trunc</primary>
8261          </indexterm>
8262          <literal><function>trunc(<type>macaddr</type>)</function></literal>
8263         </entry>
8264         <entry><type>macaddr</type></entry>
8265         <entry>set last 3 bytes to zero</entry>
8266         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
8267         <entry><literal>12:34:56:00:00:00</literal></entry>
8268        </row>
8269       </tbody>
8270      </tgroup>
8271     </table>
8272
8273    <para>
8274     The <type>macaddr</type> type also supports the standard relational
8275     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
8276     lexicographical ordering.
8277    </para>
8278
8279   </sect1>
8280
8281
8282  <sect1 id="functions-textsearch">
8283   <title>Text Search Functions and Operators</title>
8284
8285    <indexterm zone="datatype-textsearch">
8286     <primary>full text search</primary>
8287     <secondary>functions and operators</secondary>
8288    </indexterm>
8289
8290    <indexterm zone="datatype-textsearch">
8291     <primary>text search</primary>
8292     <secondary>functions and operators</secondary>
8293    </indexterm>
8294
8295   <para>
8296    <xref linkend="textsearch-operators-table">,
8297    <xref linkend="textsearch-functions-table"> and
8298    <xref linkend="textsearch-functions-debug-table">
8299    summarize the functions and operators that are provided
8300    for full text searching.  See <xref linkend="textsearch"> for a detailed
8301    explanation of <productname>PostgreSQL</productname>'s text search
8302    facility.
8303   </para>
8304
8305     <table id="textsearch-operators-table">
8306      <title>Text Search Operators</title>
8307      <tgroup cols="4">
8308       <thead>
8309        <row>
8310         <entry>Operator</entry>
8311         <entry>Description</entry>
8312         <entry>Example</entry>
8313         <entry>Result</entry>
8314        </row>
8315       </thead>
8316       <tbody>
8317        <row>
8318         <entry> <literal>@@</literal> </entry>
8319         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
8320         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
8321         <entry><literal>t</literal></entry>
8322        </row>
8323        <row>
8324         <entry> <literal>@@@</literal> </entry>
8325         <entry>deprecated synonym for <literal>@@</></entry>
8326         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
8327         <entry><literal>t</literal></entry>
8328        </row>
8329        <row>
8330         <entry> <literal>||</literal> </entry>
8331         <entry>concatenate <type>tsvector</>s</entry>
8332         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
8333         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
8334        </row>
8335        <row>
8336         <entry> <literal>&amp;&amp;</literal> </entry>
8337         <entry>AND <type>tsquery</>s together</entry>
8338         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
8339         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
8340        </row>
8341        <row>
8342         <entry> <literal>||</literal> </entry>
8343         <entry>OR <type>tsquery</>s together</entry>
8344         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
8345         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
8346        </row>
8347        <row>
8348         <entry> <literal>!!</literal> </entry>
8349         <entry>negate a <type>tsquery</></entry>
8350         <entry><literal>!! 'cat'::tsquery</literal></entry>
8351         <entry><literal>!'cat'</literal></entry>
8352        </row>
8353        <row>
8354         <entry> <literal>@&gt;</literal> </entry>
8355         <entry><type>tsquery</> contains another ?</entry>
8356         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
8357         <entry><literal>f</literal></entry>
8358        </row>
8359        <row>
8360         <entry> <literal>&lt;@</literal> </entry>
8361         <entry><type>tsquery</> is contained in ?</entry>
8362         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
8363         <entry><literal>t</literal></entry>
8364        </row>
8365       </tbody>
8366      </tgroup>
8367     </table>
8368
8369     <note>
8370      <para>
8371       The <type>tsquery</> containment operators consider only the lexemes
8372       listed in the two queries, ignoring the combining operators.
8373      </para>
8374     </note>
8375
8376     <para>
8377      In addition to the operators shown in the table, the ordinary B-tree
8378      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
8379      for types <type>tsvector</> and <type>tsquery</>.  These are not very
8380      useful for text searching but allow, for example, unique indexes to be
8381      built on columns of these types.
8382     </para>
8383
8384     <table id="textsearch-functions-table">
8385      <title>Text Search Functions</title>
8386      <tgroup cols="5">
8387       <thead>
8388        <row>
8389         <entry>Function</entry>
8390         <entry>Return Type</entry>
8391         <entry>Description</entry>
8392         <entry>Example</entry>
8393         <entry>Result</entry>
8394        </row>
8395       </thead>
8396       <tbody>
8397        <row>
8398         <entry>
8399          <indexterm>
8400           <primary>get_current_ts_config</primary>
8401          </indexterm>
8402          <literal><function>get_current_ts_config()</function></literal>
8403         </entry>
8404         <entry><type>regconfig</type></entry>
8405         <entry>get default text search configuration</entry>
8406         <entry><literal>get_current_ts_config()</literal></entry>
8407         <entry><literal>english</literal></entry>
8408        </row>
8409        <row>
8410         <entry>
8411          <indexterm>
8412           <primary>length</primary>
8413          </indexterm>
8414          <literal><function>length(<type>tsvector</>)</function></literal>
8415         </entry>
8416         <entry><type>integer</type></entry>
8417         <entry>number of lexemes in <type>tsvector</></entry>
8418         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
8419         <entry><literal>3</literal></entry>
8420        </row>
8421        <row>
8422         <entry>
8423          <indexterm>
8424           <primary>numnode</primary>
8425          </indexterm>
8426          <literal><function>numnode(<type>tsquery</>)</function></literal>
8427         </entry>
8428         <entry><type>integer</type></entry>
8429         <entry>number of lexemes plus operators in <type>tsquery</></entry>
8430         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
8431         <entry><literal>5</literal></entry>
8432        </row>
8433        <row>
8434         <entry>
8435          <indexterm>
8436           <primary>plainto_tsquery</primary>
8437          </indexterm>
8438          <literal><function>plainto_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
8439         </entry>
8440         <entry><type>tsquery</type></entry>
8441         <entry>produce <type>tsquery</> ignoring punctuation</entry>
8442         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
8443         <entry><literal>'fat' &amp; 'rat'</literal></entry>
8444        </row>
8445        <row>
8446         <entry>
8447          <indexterm>
8448           <primary>querytree</primary>
8449          </indexterm>
8450          <literal><function>querytree(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</function></literal>
8451         </entry>
8452         <entry><type>text</type></entry>
8453         <entry>get indexable part of a <type>tsquery</></entry>
8454         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
8455         <entry><literal>'foo'</literal></entry>
8456        </row>
8457        <row>
8458         <entry>
8459          <indexterm>
8460           <primary>setweight</primary>
8461          </indexterm>
8462          <literal><function>setweight(<type>tsvector</>, <type>"char"</>)</function></literal>
8463         </entry>
8464         <entry><type>tsvector</type></entry>
8465         <entry>assign weight to each element of <type>tsvector</></entry>
8466         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
8467         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
8468        </row>
8469        <row>
8470         <entry>
8471          <indexterm>
8472           <primary>strip</primary>
8473          </indexterm>
8474          <literal><function>strip(<type>tsvector</>)</function></literal>
8475         </entry>
8476         <entry><type>tsvector</type></entry>
8477         <entry>remove positions and weights from <type>tsvector</></entry>
8478         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
8479         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
8480        </row>
8481        <row>
8482         <entry>
8483          <indexterm>
8484           <primary>to_tsquery</primary>
8485          </indexterm>
8486          <literal><function>to_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
8487         </entry>
8488         <entry><type>tsquery</type></entry>
8489         <entry>normalize words and convert to <type>tsquery</></entry>
8490         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
8491         <entry><literal>'fat' &amp; 'rat'</literal></entry>
8492        </row>
8493        <row>
8494         <entry>
8495          <indexterm>
8496           <primary>to_tsvector</primary>
8497          </indexterm>
8498          <literal><function>to_tsvector(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</function></literal>
8499         </entry>
8500         <entry><type>tsvector</type></entry>
8501         <entry>reduce document text to <type>tsvector</></entry>
8502         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
8503         <entry><literal>'fat':2 'rat':3</literal></entry>
8504        </row>
8505        <row>
8506         <entry>
8507          <indexterm>
8508           <primary>ts_headline</primary>
8509          </indexterm>
8510          <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>
8511         </entry>
8512         <entry><type>text</type></entry>
8513         <entry>display a query match</entry>
8514         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
8515         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
8516        </row>
8517        <row>
8518         <entry>
8519          <indexterm>
8520           <primary>ts_rank</primary>
8521          </indexterm>
8522          <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>
8523         </entry>
8524         <entry><type>float4</type></entry>
8525         <entry>rank document for query</entry>
8526         <entry><literal>ts_rank(textsearch, query)</literal></entry>
8527         <entry><literal>0.818</literal></entry>
8528        </row>
8529        <row>
8530         <entry>
8531          <indexterm>
8532           <primary>ts_rank_cd</primary>
8533          </indexterm>
8534          <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>
8535         </entry>
8536         <entry><type>float4</type></entry>
8537         <entry>rank document for query using cover density</entry>
8538         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
8539         <entry><literal>2.01317</literal></entry>
8540        </row>
8541        <row>
8542         <entry>
8543          <indexterm>
8544           <primary>ts_rewrite</primary>
8545          </indexterm>
8546          <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>
8547         </entry>
8548         <entry><type>tsquery</type></entry>
8549         <entry>replace target with substitute within query</entry>
8550         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
8551         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
8552        </row>
8553        <row>
8554         <entry><literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</function></literal></entry>
8555         <entry><type>tsquery</type></entry>
8556         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
8557         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
8558         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
8559        </row>
8560        <row>
8561         <entry>
8562          <indexterm>
8563           <primary>tsvector_update_trigger</primary>
8564          </indexterm>
8565          <literal><function>tsvector_update_trigger()</function></literal>
8566         </entry>
8567         <entry><type>trigger</type></entry>
8568         <entry>trigger function for automatic <type>tsvector</> column update</entry>
8569         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
8570         <entry><literal></literal></entry>
8571        </row>
8572        <row>
8573         <entry>
8574          <indexterm>
8575           <primary>tsvector_update_trigger_column</primary>
8576          </indexterm>
8577          <literal><function>tsvector_update_trigger_column()</function></literal>
8578         </entry>
8579         <entry><type>trigger</type></entry>
8580         <entry>trigger function for automatic <type>tsvector</> column update</entry>
8581         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
8582         <entry><literal></literal></entry>
8583        </row>
8584       </tbody>
8585      </tgroup>
8586     </table>
8587
8588   <note>
8589    <para>
8590     All the text search functions that accept an optional <type>regconfig</>
8591     argument will use the configuration specified by
8592     <xref linkend="guc-default-text-search-config">
8593     when that argument is omitted.
8594    </para>
8595   </note>
8596
8597   <para>
8598    The functions in
8599    <xref linkend="textsearch-functions-debug-table">
8600    are listed separately because they are not usually used in everyday text
8601    searching operations.  They are helpful for development and debugging
8602    of new text search configurations.
8603   </para>
8604
8605     <table id="textsearch-functions-debug-table">
8606      <title>Text Search Debugging Functions</title>
8607      <tgroup cols="5">
8608       <thead>
8609        <row>
8610         <entry>Function</entry>
8611         <entry>Return Type</entry>
8612         <entry>Description</entry>
8613         <entry>Example</entry>
8614         <entry>Result</entry>
8615        </row>
8616       </thead>
8617       <tbody>
8618        <row>
8619         <entry>
8620          <indexterm>
8621           <primary>ts_debug</primary>
8622          </indexterm>
8623          <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>
8624         </entry>
8625         <entry><type>setof record</type></entry>
8626         <entry>test a configuration</entry>
8627         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
8628         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
8629        </row>
8630        <row>
8631         <entry>
8632          <indexterm>
8633           <primary>ts_lexize</primary>
8634          </indexterm>
8635          <literal><function>ts_lexize(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</function></literal>
8636         </entry>
8637         <entry><type>text[]</type></entry>
8638         <entry>test a dictionary</entry>
8639         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
8640         <entry><literal>{star}</literal></entry>
8641        </row>
8642        <row>
8643         <entry>
8644          <indexterm>
8645           <primary>ts_parse</primary>
8646          </indexterm>
8647          <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>
8648         </entry>
8649         <entry><type>setof record</type></entry>
8650         <entry>test a parser</entry>
8651         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
8652         <entry><literal>(1,foo) ...</literal></entry>
8653        </row>
8654        <row>
8655         <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>
8656         <entry><type>setof record</type></entry>
8657         <entry>test a parser</entry>
8658         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
8659         <entry><literal>(1,foo) ...</literal></entry>
8660        </row>
8661        <row>
8662         <entry>
8663          <indexterm>
8664           <primary>ts_token_type</primary>
8665          </indexterm>
8666          <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>
8667         </entry>
8668         <entry><type>setof record</type></entry>
8669         <entry>get token types defined by parser</entry>
8670         <entry><literal>ts_token_type('default')</literal></entry>
8671         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8672        </row>
8673        <row>
8674         <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>
8675         <entry><type>setof record</type></entry>
8676         <entry>get token types defined by parser</entry>
8677         <entry><literal>ts_token_type(3722)</literal></entry>
8678         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8679        </row>
8680        <row>
8681         <entry>
8682          <indexterm>
8683           <primary>ts_stat</primary>
8684          </indexterm>
8685          <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>
8686         </entry>
8687         <entry><type>setof record</type></entry>
8688         <entry>get statistics of a <type>tsvector</> column</entry>
8689         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
8690         <entry><literal>(foo,10,15) ...</literal></entry>
8691        </row>
8692       </tbody>
8693      </tgroup>
8694     </table>
8695
8696  </sect1>
8697
8698
8699  <sect1 id="functions-xml">
8700   <title>XML Functions</title>
8701
8702   <para>
8703    The functions and function-like expressions described in this
8704    section operate on values of type <type>xml</type>.  Check <xref
8705    linkend="datatype-xml"> for information about the <type>xml</type>
8706    type.  The function-like expressions <function>xmlparse</function>
8707    and <function>xmlserialize</function> for converting to and from
8708    type <type>xml</type> are not repeated here.  Use of most of these
8709    functions requires the installation to have been built
8710    with <command>configure --with-libxml</>.
8711   </para>
8712
8713   <sect2>
8714    <title>Producing XML Content</title>
8715
8716    <para>
8717     A set of functions and function-like expressions are available for
8718     producing XML content from SQL data.  As such, they are
8719     particularly suitable for formatting query results into XML
8720     documents for processing in client applications.
8721    </para>
8722
8723    <sect3>
8724     <title><literal>xmlcomment</literal></title>
8725
8726     <indexterm>
8727      <primary>xmlcomment</primary>
8728     </indexterm>
8729
8730 <synopsis>
8731 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8732 </synopsis>
8733
8734     <para>
8735      The function <function>xmlcomment</function> creates an XML value
8736      containing an XML comment with the specified text as content.
8737      The text cannot contain <quote><literal>--</literal></quote> or end with a
8738      <quote><literal>-</literal></quote> so that the resulting construct is a valid
8739      XML comment.  If the argument is null, the result is null.
8740     </para>
8741
8742     <para>
8743      Example:
8744 <screen><![CDATA[
8745 SELECT xmlcomment('hello');
8746
8747   xmlcomment
8748 --------------
8749  <!--hello-->
8750 ]]></screen>
8751     </para>
8752    </sect3>
8753
8754    <sect3>
8755     <title><literal>xmlconcat</literal></title>
8756
8757     <indexterm>
8758      <primary>xmlconcat</primary>
8759     </indexterm>
8760
8761 <synopsis>
8762 <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8763 </synopsis>
8764
8765     <para>
8766      The function <function>xmlconcat</function> concatenates a list
8767      of individual XML values to create a single value containing an
8768      XML content fragment.  Null values are omitted; the result is
8769      only null if there are no nonnull arguments.
8770     </para>
8771
8772     <para>
8773      Example:
8774 <screen><![CDATA[
8775 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8776
8777       xmlconcat
8778 ----------------------
8779  <abc/><bar>foo</bar>
8780 ]]></screen>
8781     </para>
8782
8783     <para>
8784      XML declarations, if present, are combined as follows.  If all
8785      argument values have the same XML version declaration, that
8786      version is used in the result, else no version is used.  If all
8787      argument values have the standalone declaration value
8788      <quote>yes</quote>, then that value is used in the result.  If
8789      all argument values have a standalone declaration value and at
8790      least one is <quote>no</quote>, then that is used in the result.
8791      Else the result will have no standalone declaration.  If the
8792      result is determined to require a standalone declaration but no
8793      version declaration, a version declaration with version 1.0 will
8794      be used because XML requires an XML declaration to contain a
8795      version declaration.  Encoding declarations are ignored and
8796      removed in all cases.
8797     </para>
8798
8799     <para>
8800      Example:
8801 <screen><![CDATA[
8802 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
8803
8804              xmlconcat
8805 -----------------------------------
8806  <?xml version="1.1"?><foo/><bar/>
8807 ]]></screen>
8808     </para>
8809    </sect3>
8810
8811    <sect3>
8812     <title><literal>xmlelement</literal></title>
8813
8814    <indexterm>
8815     <primary>xmlelement</primary>
8816    </indexterm>
8817
8818 <synopsis>
8819 <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>)
8820 </synopsis>
8821
8822     <para>
8823      The <function>xmlelement</function> expression produces an XML
8824      element with the given name, attributes, and content.
8825     </para>
8826
8827     <para>
8828      Examples:
8829 <screen><![CDATA[
8830 SELECT xmlelement(name foo);
8831
8832  xmlelement
8833 ------------
8834  <foo/>
8835
8836 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8837
8838     xmlelement
8839 ------------------
8840  <foo bar="xyz"/>
8841
8842 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8843
8844              xmlelement
8845 -------------------------------------
8846  <foo bar="2007-01-26">content</foo>
8847 ]]></screen>
8848     </para>
8849
8850     <para>
8851      Element and attribute names that are not valid XML names are
8852      escaped by replacing the offending characters by the sequence
8853      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8854      <replaceable>HHHH</replaceable> is the character's Unicode
8855      codepoint in hexadecimal notation.  For example:
8856 <screen><![CDATA[
8857 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
8858
8859             xmlelement
8860 ----------------------------------
8861  <foo_x0024_bar a_x0026_b="xyz"/>
8862 ]]></screen>
8863     </para>
8864
8865     <para>
8866      An explicit attribute name need not be specified if the attribute
8867      value is a column reference, in which case the column's name will
8868      be used as the attribute name by default.  In other cases, the
8869      attribute must be given an explicit name.  So this example is
8870      valid:
8871 <screen>
8872 CREATE TABLE test (a xml, b xml);
8873 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8874 </screen>
8875      But these are not:
8876 <screen>
8877 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8878 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8879 </screen>
8880     </para>
8881
8882     <para>
8883      Element content, if specified, will be formatted according to
8884      its data type.  If the content is itself of type <type>xml</type>,
8885      complex XML documents can be constructed.  For example:
8886 <screen><![CDATA[
8887 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8888                             xmlelement(name abc),
8889                             xmlcomment('test'),
8890                             xmlelement(name xyz));
8891
8892                   xmlelement
8893 ----------------------------------------------
8894  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
8895 ]]></screen>
8896
8897      Content of other types will be formatted into valid XML character
8898      data.  This means in particular that the characters &lt;, &gt;,
8899      and &amp; will be converted to entities.  Binary data (data type
8900      <type>bytea</type>) will be represented in base64 or hex
8901      encoding, depending on the setting of the configuration parameter
8902      <xref linkend="guc-xmlbinary">.  The particular behavior for
8903      individual data types is expected to evolve in order to align the
8904      SQL and PostgreSQL data types with the XML Schema specification,
8905      at which point a more precise description will appear.
8906     </para>
8907    </sect3>
8908
8909    <sect3>
8910     <title><literal>xmlforest</literal></title>
8911
8912    <indexterm>
8913     <primary>xmlforest</primary>
8914    </indexterm>
8915
8916 <synopsis>
8917 <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8918 </synopsis>
8919
8920     <para>
8921      The <function>xmlforest</function> expression produces an XML
8922      forest (sequence) of elements using the given names and content.
8923     </para>
8924
8925     <para>
8926      Examples:
8927 <screen><![CDATA[
8928 SELECT xmlforest('abc' AS foo, 123 AS bar);
8929
8930           xmlforest
8931 ------------------------------
8932  <foo>abc</foo><bar>123</bar>
8933
8934
8935 SELECT xmlforest(table_name, column_name)
8936 FROM information_schema.columns
8937 WHERE table_schema = 'pg_catalog';
8938
8939                                          xmlforest
8940 -------------------------------------------------------------------------------------------
8941  <table_name>pg_authid</table_name><column_name>rolname</column_name>
8942  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8943  ...
8944 ]]></screen>
8945
8946      As seen in the second example, the element name can be omitted if
8947      the content value is a column reference, in which case the column
8948      name is used by default.  Otherwise, a name must be specified.
8949     </para>
8950
8951     <para>
8952      Element names that are not valid XML names are escaped as shown
8953      for <function>xmlelement</function> above.  Similarly, content
8954      data is escaped to make valid XML content, unless it is already
8955      of type <type>xml</type>.
8956     </para>
8957
8958     <para>
8959      Note that XML forests are not valid XML documents if they consist
8960      of more than one element, so it might be useful to wrap
8961      <function>xmlforest</function> expressions in
8962      <function>xmlelement</function>.
8963     </para>
8964    </sect3>
8965
8966    <sect3>
8967     <title><literal>xmlpi</literal></title>
8968
8969    <indexterm>
8970     <primary>xmlpi</primary>
8971    </indexterm>
8972
8973 <synopsis>
8974 <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
8975 </synopsis>
8976
8977     <para>
8978      The <function>xmlpi</function> expression creates an XML
8979      processing instruction.  The content, if present, must not
8980      contain the character sequence <literal>?&gt;</literal>.
8981     </para>
8982
8983     <para>
8984      Example:
8985 <screen><![CDATA[
8986 SELECT xmlpi(name php, 'echo "hello world";');
8987
8988             xmlpi
8989 -----------------------------
8990  <?php echo "hello world";?>
8991 ]]></screen>
8992     </para>
8993    </sect3>
8994
8995    <sect3>
8996     <title><literal>xmlroot</literal></title>
8997
8998    <indexterm>
8999     <primary>xmlroot</primary>
9000    </indexterm>
9001
9002 <synopsis>
9003 <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
9004 </synopsis>
9005
9006     <para>
9007      The <function>xmlroot</function> expression alters the properties
9008      of the root node of an XML value.  If a version is specified,
9009      it replaces the value in the root node's version declaration; if a
9010      standalone setting is specified, it replaces the value in the
9011      root node's standalone declaration.
9012     </para>
9013
9014     <para>
9015 <screen><![CDATA[
9016 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
9017                version '1.0', standalone yes);
9018
9019                 xmlroot
9020 ----------------------------------------
9021  <?xml version="1.0" standalone="yes"?>
9022  <content>abc</content>
9023 ]]></screen>
9024     </para>
9025    </sect3>
9026
9027    <sect3 id="functions-xml-xmlagg">
9028     <title><literal>xmlagg</literal></title>
9029
9030     <indexterm>
9031      <primary>xmlagg</primary>
9032     </indexterm>
9033
9034 <synopsis>
9035 <function>xmlagg</function>(<replaceable>xml</replaceable>)
9036 </synopsis>
9037
9038     <para>
9039      The function <function>xmlagg</function> is, unlike the other
9040      functions described here, an aggregate function.  It concatenates the
9041      input values to the aggregate function call,
9042      much like <function>xmlconcat</function> does, except that concatenation
9043      occurs across rows rather than across expressions in a single row.
9044      See <xref linkend="functions-aggregate"> for additional information
9045      about aggregate functions.
9046     </para>
9047
9048     <para>
9049      Example:
9050 <screen><![CDATA[
9051 CREATE TABLE test (y int, x xml);
9052 INSERT INTO test VALUES (1, '<foo>abc</foo>');
9053 INSERT INTO test VALUES (2, '<bar/>');
9054 SELECT xmlagg(x) FROM test;
9055         xmlagg
9056 ----------------------
9057  <foo>abc</foo><bar/>
9058 ]]></screen>
9059     </para>
9060
9061     <para>
9062      To determine the order of the concatenation, an <literal>ORDER BY</>
9063      clause may be added to the aggregate call as described in
9064      <xref linkend="syntax-aggregates">. For example:
9065
9066 <screen><![CDATA[
9067 SELECT xmlagg(x ORDER BY y DESC) FROM test;
9068         xmlagg
9069 ----------------------
9070  <bar/><foo>abc</foo>
9071 ]]></screen>
9072     </para>
9073
9074     <para>
9075      The following non-standard approach used to be recommended
9076      in previous versions, and may still be useful in specific
9077      cases:
9078
9079 <screen><![CDATA[
9080 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
9081         xmlagg
9082 ----------------------
9083  <bar/><foo>abc</foo>
9084 ]]></screen>
9085     </para>
9086    </sect3>
9087    </sect2>
9088
9089    <sect2>
9090     <title>XML Predicates</title>
9091
9092     <para>
9093      The expressions described in this section check properties
9094      of <type>xml</type> values.
9095     </para>
9096
9097    <sect3>
9098     <title>IS DOCUMENT</title>
9099
9100     <indexterm>
9101      <primary>IS DOCUMENT</primary>
9102     </indexterm>
9103
9104 <synopsis>
9105 <replaceable>xml</replaceable> IS DOCUMENT
9106 </synopsis>
9107
9108     <para>
9109      The expression <literal>IS DOCUMENT</literal> returns true if the
9110      argument XML value is a proper XML document, false if it is not
9111      (that is, it is a content fragment), or null if the argument is
9112      null.  See <xref linkend="datatype-xml"> about the difference
9113      between documents and content fragments.
9114     </para>
9115    </sect3>
9116
9117    <sect3>
9118     <title>XMLEXISTS</title>
9119
9120     <indexterm>
9121      <primary>XMLEXISTS</primary>
9122     </indexterm>
9123
9124 <synopsis>
9125 <function>XMLEXISTS</function>(<replaceable>text</replaceable> PASSING <optional>BY REF</optional> <replaceable>xml</replaceable> <optional>BY REF</optional>)
9126 </synopsis>
9127
9128     <para>
9129      The function <function>xmlexists</function> returns true if the
9130      XPath expression in the first argument returns any nodes, and
9131      false otherwise.  (If either argument is null, the result is
9132      null.)
9133     </para>
9134
9135     <para>
9136      Example:
9137      <screen><![CDATA[
9138 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY REF '<towns><town>Toronto</town><town>Ottawa</town></towns>');
9139
9140  xmlexists
9141 ------------
9142  t
9143 (1 row)
9144 ]]></screen>
9145     </para>
9146
9147     <para>
9148      The <literal>BY REF</literal> clauses have no effect in
9149      PostgreSQL, but are allowed for SQL conformance and compatibility
9150      with other implementations.  Per SQL standard, the
9151      first <literal>BY REF</literal> is required, the second is
9152      optional.  Also note that the SQL standard specifies
9153      the <function>xmlexists</function> construct to take an XQuery
9154      expression as first argument, but PostgreSQL currently only
9155      supports XPath, which is a subset of XQuery.
9156     </para>
9157    </sect3>
9158
9159    <sect3>
9160     <title>xml_is_well_formed</title>
9161
9162     <indexterm>
9163      <primary>xml_is_well_formed</primary>
9164     </indexterm>
9165
9166     <indexterm>
9167      <primary>xml_is_well_formed_document</primary>
9168     </indexterm>
9169
9170     <indexterm>
9171      <primary>xml_is_well_formed_content</primary>
9172     </indexterm>
9173
9174 <synopsis>
9175 <function>xml_is_well_formed</function>(<replaceable>text</replaceable>)
9176 <function>xml_is_well_formed_document</function>(<replaceable>text</replaceable>)
9177 <function>xml_is_well_formed_content</function>(<replaceable>text</replaceable>)
9178 </synopsis>
9179
9180     <para>
9181      These functions check whether a <type>text</> string is well-formed XML,
9182      returning a boolean result.
9183      <function>xml_is_well_formed_document</function> checks for a well-formed
9184      document, while <function>xml_is_well_formed_content</function> checks
9185      for well-formed content.  <function>xml_is_well_formed</function> does
9186      the former if the <xref linkend="guc-xmloption"> configuration
9187      parameter is set to <literal>DOCUMENT</>, or the latter if it is set to
9188      <literal>CONTENT</>.  This means that
9189      <function>xml_is_well_formed</function> is useful for seeing whether
9190      a simple cast to type <type>xml</> will succeed, whereas the other two
9191      functions are useful for seeing whether the corresponding variants of
9192      <function>XMLPARSE</> will succeed.
9193     </para>
9194
9195     <para>
9196      Examples:
9197
9198 <screen><![CDATA[
9199 SET xmloption TO DOCUMENT;
9200 SELECT xml_is_well_formed('<>');
9201  xml_is_well_formed 
9202 --------------------
9203  f
9204 (1 row)
9205
9206 SELECT xml_is_well_formed('<abc/>');
9207  xml_is_well_formed 
9208 --------------------
9209  t
9210 (1 row)
9211
9212 SET xmloption TO CONTENT;
9213 SELECT xml_is_well_formed('abc');
9214  xml_is_well_formed 
9215 --------------------
9216  t
9217 (1 row)
9218
9219 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
9220  xml_is_well_formed_document 
9221 -----------------------------
9222  t
9223 (1 row)
9224
9225 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
9226  xml_is_well_formed_document 
9227 -----------------------------
9228  f
9229 (1 row)
9230 ]]></screen>
9231
9232      The last example shows that the checks include whether
9233      namespaces are correctly matched.
9234     </para>
9235    </sect3>
9236   </sect2>
9237
9238   <sect2 id="functions-xml-processing">
9239    <title>Processing XML</title>
9240
9241    <indexterm>
9242     <primary>XPath</primary>
9243    </indexterm>
9244
9245    <para>
9246     To process values of data type <type>xml</type>, PostgreSQL offers
9247     the functions <function>xpath</function> and
9248     <function>xpath_exists</function>, which evaluate XPath 1.0
9249     expressions.
9250    </para>
9251
9252 <synopsis>
9253 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9254 </synopsis>
9255
9256    <para>
9257     The function <function>xpath</function> evaluates the XPath
9258     expression <replaceable>xpath</replaceable> (a <type>text</> value)
9259     against the XML value
9260     <replaceable>xml</replaceable>.  It returns an array of XML values
9261     corresponding to the node set produced by the XPath expression.
9262    </para>
9263
9264   <para>
9265     The second argument must be a well formed XML document. In particular,
9266     it must have a single root node element.
9267   </para>
9268
9269    <para>
9270     The optional third argument of the function is an array of namespace
9271     mappings.  This array should be a two-dimensional <type>text</> array with
9272     the length of the second axis being equal to 2 (i.e., it should be an
9273     array of arrays, each of which consists of exactly 2 elements).
9274     The first element of each array entry is the namespace name (alias), the
9275     second the namespace URI. It is not required that aliases provided in
9276     this array be the same as those being used in the XML document itself (in
9277     other words, both in the XML document and in the <function>xpath</function>
9278     function context, aliases are <emphasis>local</>).
9279    </para>
9280
9281    <para>
9282     Example:
9283 <screen><![CDATA[
9284 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9285              ARRAY[ARRAY['my', 'http://example.com']]);
9286
9287  xpath  
9288 --------
9289  {test}
9290 (1 row)
9291 ]]></screen>
9292    </para>
9293
9294    <para>
9295     To deal with default (anonymous) namespaces, do something like this:
9296 <screen><![CDATA[
9297 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
9298              ARRAY[ARRAY['mydefns', 'http://example.com']]);
9299
9300  xpath
9301 --------
9302  {test}
9303 (1 row)
9304 ]]></screen>
9305    </para>
9306
9307    <indexterm>
9308     <primary>xpath_exists</primary>
9309    </indexterm>
9310
9311 <synopsis>
9312 <function>xpath_exists</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
9313 </synopsis>
9314
9315    <para>
9316     The function <function>xpath_exists</function> is a specialized form
9317     of the <function>xpath</function> function.  Instead of returning the
9318     individual XML values that satisfy the XPath, this function returns a
9319     boolean indicating whether the query was satisfied or not.  This
9320     function is equivalent to the standard <literal>XMLEXISTS</> predicate,
9321     except that it also offers support for a namespace mapping argument.
9322    </para>
9323
9324    <para>
9325     Example:
9326 <screen><![CDATA[
9327 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
9328                      ARRAY[ARRAY['my', 'http://example.com']]);
9329
9330  xpath_exists  
9331 --------------
9332  t
9333 (1 row)
9334 ]]></screen>
9335    </para>
9336   </sect2>
9337
9338   <sect2 id="functions-xml-mapping">
9339    <title>Mapping Tables to XML</title>
9340
9341    <indexterm zone="functions-xml-mapping">
9342     <primary>XML export</primary>
9343    </indexterm>
9344
9345    <para>
9346     The following functions map the contents of relational tables to
9347     XML values.  They can be thought of as XML export functionality:
9348 <synopsis>
9349 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9350 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
9351 cursor_to_xml(cursor refcursor, count int, nulls boolean,
9352               tableforest boolean, targetns text)
9353 </synopsis>
9354     The return type of each function is <type>xml</type>.
9355    </para>
9356
9357    <para>
9358     <function>table_to_xml</function> maps the content of the named
9359     table, passed as parameter <parameter>tbl</parameter>.  The
9360     <type>regclass</type> type accepts strings identifying tables using the
9361     usual notation, including optional schema qualifications and
9362     double quotes.  <function>query_to_xml</function> executes the
9363     query whose text is passed as parameter
9364     <parameter>query</parameter> and maps the result set.
9365     <function>cursor_to_xml</function> fetches the indicated number of
9366     rows from the cursor specified by the parameter
9367     <parameter>cursor</parameter>.  This variant is recommended if
9368     large tables have to be mapped, because the result value is built
9369     up in memory by each function.
9370    </para>
9371
9372    <para>
9373     If <parameter>tableforest</parameter> is false, then the resulting
9374     XML document looks like this:
9375 <screen><![CDATA[
9376 <tablename>
9377   <row>
9378     <columnname1>data</columnname1>
9379     <columnname2>data</columnname2>
9380   </row>
9381
9382   <row>
9383     ...
9384   </row>
9385
9386   ...
9387 </tablename>
9388 ]]></screen>
9389
9390     If <parameter>tableforest</parameter> is true, the result is an
9391     XML content fragment that looks like this:
9392 <screen><![CDATA[
9393 <tablename>
9394   <columnname1>data</columnname1>
9395   <columnname2>data</columnname2>
9396 </tablename>
9397
9398 <tablename>
9399   ...
9400 </tablename>
9401
9402 ...
9403 ]]></screen>
9404
9405     If no table name is available, that is, when mapping a query or a
9406     cursor, the string <literal>table</literal> is used in the first
9407     format, <literal>row</literal> in the second format.
9408    </para>
9409
9410    <para>
9411     The choice between these formats is up to the user.  The first
9412     format is a proper XML document, which will be important in many
9413     applications.  The second format tends to be more useful in the
9414     <function>cursor_to_xml</function> function if the result values are to be
9415     reassembled into one document later on.  The functions for
9416     producing XML content discussed above, in particular
9417     <function>xmlelement</function>, can be used to alter the results
9418     to taste.
9419    </para>
9420
9421    <para>
9422     The data values are mapped in the same way as described for the
9423     function <function>xmlelement</function> above.
9424    </para>
9425
9426    <para>
9427     The parameter <parameter>nulls</parameter> determines whether null
9428     values should be included in the output.  If true, null values in
9429     columns are represented as:
9430 <screen><![CDATA[
9431 <columnname xsi:nil="true"/>
9432 ]]></screen>
9433     where <literal>xsi</literal> is the XML namespace prefix for XML
9434     Schema Instance.  An appropriate namespace declaration will be
9435     added to the result value.  If false, columns containing null
9436     values are simply omitted from the output.
9437    </para>
9438
9439    <para>
9440     The parameter <parameter>targetns</parameter> specifies the
9441     desired XML namespace of the result.  If no particular namespace
9442     is wanted, an empty string should be passed.
9443    </para>
9444
9445    <para>
9446     The following functions return XML Schema documents describing the
9447     mappings performed by the corresponding functions above:
9448 <synopsis>
9449 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9450 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9451 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
9452 </synopsis>
9453     It is essential that the same parameters are passed in order to
9454     obtain matching XML data mappings and XML Schema documents.
9455    </para>
9456
9457    <para>
9458     The following functions produce XML data mappings and the
9459     corresponding XML Schema in one document (or forest), linked
9460     together.  They can be useful where self-contained and
9461     self-describing results are wanted:
9462 <synopsis>
9463 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9464 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9465 </synopsis>
9466    </para>
9467
9468    <para>
9469     In addition, the following functions are available to produce
9470     analogous mappings of entire schemas or the entire current
9471     database:
9472 <synopsis>
9473 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
9474 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9475 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9476
9477 database_to_xml(nulls boolean, tableforest boolean, targetns text)
9478 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
9479 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
9480 </synopsis>
9481
9482     Note that these potentially produce a lot of data, which needs to
9483     be built up in memory.  When requesting content mappings of large
9484     schemas or databases, it might be worthwhile to consider mapping the
9485     tables separately instead, possibly even through a cursor.
9486    </para>
9487
9488    <para>
9489     The result of a schema content mapping looks like this:
9490
9491 <screen><![CDATA[
9492 <schemaname>
9493
9494 table1-mapping
9495
9496 table2-mapping
9497
9498 ...
9499
9500 </schemaname>]]></screen>
9501
9502     where the format of a table mapping depends on the
9503     <parameter>tableforest</parameter> parameter as explained above.
9504    </para>
9505
9506    <para>
9507     The result of a database content mapping looks like this:
9508
9509 <screen><![CDATA[
9510 <dbname>
9511
9512 <schema1name>
9513   ...
9514 </schema1name>
9515
9516 <schema2name>
9517   ...
9518 </schema2name>
9519
9520 ...
9521
9522 </dbname>]]></screen>
9523
9524     where the schema mapping is as above.
9525    </para>
9526
9527    <para>
9528     As an example of using the output produced by these functions,
9529     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
9530     converts the output of
9531     <function>table_to_xml_and_xmlschema</function> to an HTML
9532     document containing a tabular rendition of the table data.  In a
9533     similar manner, the results from these functions can be
9534     converted into other XML-based formats.
9535    </para>
9536
9537    <figure id="xslt-xml-html">
9538     <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
9539 <programlisting><![CDATA[
9540 <?xml version="1.0"?>
9541 <xsl:stylesheet version="1.0"
9542     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
9543     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
9544     xmlns="http://www.w3.org/1999/xhtml"
9545 >
9546
9547   <xsl:output method="xml"
9548       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
9549       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
9550       indent="yes"/>
9551
9552   <xsl:template match="/*">
9553     <xsl:variable name="schema" select="//xsd:schema"/>
9554     <xsl:variable name="tabletypename"
9555                   select="$schema/xsd:element[@name=name(current())]/@type"/>
9556     <xsl:variable name="rowtypename"
9557                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
9558
9559     <html>
9560       <head>
9561         <title><xsl:value-of select="name(current())"/></title>
9562       </head>
9563       <body>
9564         <table>
9565           <tr>
9566             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
9567               <th><xsl:value-of select="."/></th>
9568             </xsl:for-each>
9569           </tr>
9570
9571           <xsl:for-each select="row">
9572             <tr>
9573               <xsl:for-each select="*">
9574                 <td><xsl:value-of select="."/></td>
9575               </xsl:for-each>
9576             </tr>
9577           </xsl:for-each>
9578         </table>
9579       </body>
9580     </html>
9581   </xsl:template>
9582
9583 </xsl:stylesheet>
9584 ]]></programlisting>
9585    </figure>
9586   </sect2>
9587  </sect1>
9588
9589
9590  <sect1 id="functions-sequence">
9591   <title>Sequence Manipulation Functions</title>
9592
9593   <indexterm>
9594    <primary>sequence</primary>
9595   </indexterm>
9596   <indexterm>
9597    <primary>nextval</primary>
9598   </indexterm>
9599   <indexterm>
9600    <primary>currval</primary>
9601   </indexterm>
9602   <indexterm>
9603    <primary>lastval</primary>
9604   </indexterm>
9605   <indexterm>
9606    <primary>setval</primary>
9607   </indexterm>
9608
9609   <para>
9610    This section describes <productname>PostgreSQL</productname>'s
9611    functions for operating on <firstterm>sequence objects</firstterm>.
9612    Sequence objects (also called sequence generators or just
9613    sequences) are special single-row tables created with <xref
9614    linkend="sql-createsequence">.
9615    A sequence object is usually used to generate unique identifiers
9616    for rows of a table.  The sequence functions, listed in <xref
9617    linkend="functions-sequence-table">, provide simple, multiuser-safe
9618    methods for obtaining successive sequence values from sequence
9619    objects.
9620   </para>
9621
9622    <table id="functions-sequence-table">
9623     <title>Sequence Functions</title>
9624     <tgroup cols="3">
9625      <thead>
9626       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
9627      </thead>
9628
9629      <tbody>
9630       <row>
9631         <entry><literal><function>currval(<type>regclass</type>)</function></literal></entry>
9632         <entry><type>bigint</type></entry>
9633         <entry>Return value most recently obtained with
9634         <function>nextval</function> for specified sequence</entry>
9635       </row>
9636       <row>
9637         <entry><literal><function>lastval()</function></literal></entry>
9638         <entry><type>bigint</type></entry>
9639         <entry>Return value most recently obtained with
9640         <function>nextval</function> for any sequence</entry>
9641       </row>
9642       <row>
9643         <entry><literal><function>nextval(<type>regclass</type>)</function></literal></entry>
9644         <entry><type>bigint</type></entry>
9645         <entry>Advance sequence and return new value</entry>
9646       </row>
9647       <row>
9648         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>)</function></literal></entry>
9649         <entry><type>bigint</type></entry>
9650         <entry>Set sequence's current value</entry>
9651       </row>
9652       <row>
9653         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</function></literal></entry>
9654         <entry><type>bigint</type></entry>
9655         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
9656       </row>
9657      </tbody>
9658     </tgroup>
9659    </table>
9660
9661   <para>
9662    The sequence to be operated on by a sequence function is specified by
9663    a <type>regclass</> argument, which is simply the OID of the sequence in the
9664    <structname>pg_class</> system catalog.  You do not have to look up the
9665    OID by hand, however, since the <type>regclass</> data type's input
9666    converter will do the work for you.  Just write the sequence name enclosed
9667    in single quotes so that it looks like a literal constant.  For
9668    compatibility with the handling of ordinary
9669    <acronym>SQL</acronym> names, the string will be converted to lower case
9670    unless it contains double quotes around the sequence name.  Thus:
9671 <programlisting>
9672 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
9673 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
9674 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
9675 </programlisting>
9676    The sequence name can be schema-qualified if necessary:
9677 <programlisting>
9678 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
9679 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
9680 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
9681 </programlisting>
9682    See <xref linkend="datatype-oid"> for more information about
9683    <type>regclass</>.
9684   </para>
9685
9686   <note>
9687    <para>
9688     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
9689     sequence functions were of type <type>text</>, not <type>regclass</>, and
9690     the above-described conversion from a text string to an OID value would
9691     happen at run time during each call.  For backwards compatibility, this
9692     facility still exists, but internally it is now handled as an implicit
9693     coercion from <type>text</> to <type>regclass</> before the function is
9694     invoked.
9695    </para>
9696
9697    <para>
9698     When you write the argument of a sequence function as an unadorned
9699     literal string, it becomes a constant of type <type>regclass</>.
9700     Since this is really just an OID, it will track the originally
9701     identified sequence despite later renaming, schema reassignment,
9702     etc.  This <quote>early binding</> behavior is usually desirable for
9703     sequence references in column defaults and views.  But sometimes you might
9704     want <quote>late binding</> where the sequence reference is resolved
9705     at run time.  To get late-binding behavior, force the constant to be
9706     stored as a <type>text</> constant instead of <type>regclass</>:
9707 <programlisting>
9708 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
9709 </programlisting>
9710     Note that late binding was the only behavior supported in
9711     <productname>PostgreSQL</productname> releases before 8.1, so you
9712     might need to do this to preserve the semantics of old applications.
9713    </para>
9714
9715    <para>
9716     Of course, the argument of a sequence function can be an expression
9717     as well as a constant.  If it is a text expression then the implicit
9718     coercion will result in a run-time lookup.
9719    </para>
9720   </note>
9721
9722   <para>
9723    The available sequence functions are:
9724
9725     <variablelist>
9726      <varlistentry>
9727       <term><function>nextval</function></term>
9728       <listitem>
9729        <para>
9730         Advance the sequence object to its next value and return that
9731         value.  This is done atomically: even if multiple sessions
9732         execute <function>nextval</function> concurrently, each will safely receive
9733         a distinct sequence value.
9734        </para>
9735       </listitem>
9736      </varlistentry>
9737
9738      <varlistentry>
9739       <term><function>currval</function></term>
9740       <listitem>
9741        <para>
9742         Return the value most recently obtained by <function>nextval</function>
9743         for this sequence in the current session.  (An error is
9744         reported if <function>nextval</function> has never been called for this
9745         sequence in this session.)  Because this is returning
9746         a session-local value, it gives a predictable answer whether or not
9747         other sessions have executed <function>nextval</function> since the
9748         current session did.
9749        </para>
9750       </listitem>
9751      </varlistentry>
9752
9753      <varlistentry>
9754       <term><function>lastval</function></term>
9755       <listitem>
9756        <para>
9757         Return the value most recently returned by
9758         <function>nextval</> in the current session. This function is
9759         identical to <function>currval</function>, except that instead
9760         of taking the sequence name as an argument it fetches the
9761         value of the last sequence used by <function>nextval</function>
9762         in the current session. It is an error to call
9763         <function>lastval</function> if <function>nextval</function>
9764         has not yet been called in the current session.
9765        </para>
9766       </listitem>
9767      </varlistentry>
9768
9769      <varlistentry>
9770       <term><function>setval</function></term>
9771       <listitem>
9772        <para>
9773         Reset the sequence object's counter value.  The two-parameter
9774         form sets the sequence's <literal>last_value</literal> field to the
9775         specified value and sets its <literal>is_called</literal> field to
9776         <literal>true</literal>, meaning that the next
9777         <function>nextval</function> will advance the sequence before
9778         returning a value.  The value reported by <function>currval</> is
9779         also set to the specified value.  In the three-parameter form,
9780         <literal>is_called</literal> can be set to either <literal>true</literal>
9781         or <literal>false</literal>.  <literal>true</> has the same effect as
9782         the two-parameter form. If it is set to <literal>false</literal>, the
9783         next <function>nextval</function> will return exactly the specified
9784         value, and sequence advancement commences with the following
9785         <function>nextval</function>.  Furthermore, the value reported by
9786         <function>currval</> is not changed in this case (this is a change
9787         from pre-8.3 behavior).  For example,
9788
9789 <screen>
9790 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
9791 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
9792 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
9793 </screen>
9794
9795         The result returned by <function>setval</function> is just the value of its
9796         second argument.
9797        </para>
9798       </listitem>
9799      </varlistentry>
9800     </variablelist>
9801   </para>
9802
9803   <para>
9804    If a sequence object has been created with default parameters,
9805    successive <function>nextval</function> calls will return successive values
9806    beginning with 1.  Other behaviors can be obtained by using
9807    special parameters in the <xref linkend="sql-createsequence"> command;
9808    see its command reference page for more information.
9809   </para>
9810
9811   <important>
9812    <para>
9813     To avoid blocking concurrent transactions that obtain numbers from the
9814     same sequence, a <function>nextval</function> operation is never rolled back;
9815     that is, once a value has been fetched it is considered used, even if the
9816     transaction that did the <function>nextval</function> later aborts.  This means
9817     that aborted transactions might leave unused <quote>holes</quote> in the
9818     sequence of assigned values.  <function>setval</function> operations are never
9819     rolled back, either.
9820    </para>
9821   </important>
9822
9823  </sect1>
9824
9825
9826  <sect1 id="functions-conditional">
9827   <title>Conditional Expressions</title>
9828
9829   <indexterm>
9830    <primary>CASE</primary>
9831   </indexterm>
9832
9833   <indexterm>
9834    <primary>conditional expression</primary>
9835   </indexterm>
9836
9837   <para>
9838    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
9839    available in <productname>PostgreSQL</productname>.
9840   </para>
9841
9842   <tip>
9843    <para>
9844     If your needs go beyond the capabilities of these conditional
9845     expressions, you might want to consider writing a stored procedure
9846     in a more expressive programming language.
9847    </para>
9848   </tip>
9849
9850   <sect2>
9851    <title><literal>CASE</></title>
9852
9853   <para>
9854    The <acronym>SQL</acronym> <token>CASE</token> expression is a
9855    generic conditional expression, similar to if/else statements in
9856    other programming languages:
9857
9858 <synopsis>
9859 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
9860      <optional>WHEN ...</optional>
9861      <optional>ELSE <replaceable>result</replaceable></optional>
9862 END
9863 </synopsis>
9864
9865    <token>CASE</token> clauses can be used wherever
9866    an expression is valid.  Each <replaceable>condition</replaceable> is an
9867    expression that returns a <type>boolean</type> result.  If the condition's
9868    result is true, the value of the <token>CASE</token> expression is the
9869    <replaceable>result</replaceable> that follows the condition, and the
9870    remainder of the <token>CASE</token> expression is not processed.  If the
9871    condition's result is not true, any subsequent <token>WHEN</token> clauses
9872    are examined in the same manner.  If no <token>WHEN</token>
9873    <replaceable>condition</replaceable> yields true, the value of the
9874    <token>CASE</> expression is the <replaceable>result</replaceable> of the
9875    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
9876    omitted and no condition is true, the result is null.
9877   </para>
9878
9879    <para>
9880     An example:
9881 <screen>
9882 SELECT * FROM test;
9883
9884  a
9885 ---
9886  1
9887  2
9888  3
9889
9890
9891 SELECT a,
9892        CASE WHEN a=1 THEN 'one'
9893             WHEN a=2 THEN 'two'
9894             ELSE 'other'
9895        END
9896     FROM test;
9897
9898  a | case
9899 ---+-------
9900  1 | one
9901  2 | two
9902  3 | other
9903 </screen>
9904    </para>
9905
9906   <para>
9907    The data types of all the <replaceable>result</replaceable>
9908    expressions must be convertible to a single output type.
9909    See <xref linkend="typeconv-union-case"> for more details.
9910   </para>
9911
9912   <para>
9913    There is a <quote>simple</> form of <token>CASE</token> expression
9914    that is a variant of the general form above:
9915
9916 <synopsis>
9917 CASE <replaceable>expression</replaceable>
9918     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
9919     <optional>WHEN ...</optional>
9920     <optional>ELSE <replaceable>result</replaceable></optional>
9921 END
9922 </synopsis>
9923
9924    The first
9925    <replaceable>expression</replaceable> is computed, then compared to
9926    each of the <replaceable>value</replaceable> expressions in the
9927    <token>WHEN</token> clauses until one is found that is equal to it.  If
9928    no match is found, the <replaceable>result</replaceable> of the
9929    <token>ELSE</token> clause (or a null value) is returned.  This is similar
9930    to the <function>switch</function> statement in C.
9931   </para>
9932
9933    <para>
9934     The example above can be written using the simple
9935     <token>CASE</token> syntax:
9936 <screen>
9937 SELECT a,
9938        CASE a WHEN 1 THEN 'one'
9939               WHEN 2 THEN 'two'
9940               ELSE 'other'
9941        END
9942     FROM test;
9943
9944  a | case
9945 ---+-------
9946  1 | one
9947  2 | two
9948  3 | other
9949 </screen>
9950    </para>
9951
9952    <para>
9953     A <token>CASE</token> expression does not evaluate any subexpressions
9954     that are not needed to determine the result.  For example, this is a
9955     possible way of avoiding a division-by-zero failure:
9956 <programlisting>
9957 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
9958 </programlisting>
9959    </para>
9960   </sect2>
9961
9962   <sect2>
9963    <title><literal>COALESCE</></title>
9964
9965   <indexterm>
9966    <primary>COALESCE</primary>
9967   </indexterm>
9968
9969   <indexterm>
9970    <primary>NVL</primary>
9971   </indexterm>
9972
9973   <indexterm>
9974    <primary>IFNULL</primary>
9975   </indexterm>
9976
9977 <synopsis>
9978 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9979 </synopsis>
9980
9981   <para>
9982    The <function>COALESCE</function> function returns the first of its
9983    arguments that is not null.  Null is returned only if all arguments
9984    are null.  It is often used to substitute a default value for
9985    null values when data is retrieved for display, for example:
9986 <programlisting>
9987 SELECT COALESCE(description, short_description, '(none)') ...
9988 </programlisting>
9989   </para>
9990
9991    <para>
9992     Like a <token>CASE</token> expression, <function>COALESCE</function> only
9993     evaluates the arguments that are needed to determine the result;
9994     that is, arguments to the right of the first non-null argument are
9995     not evaluated.  This SQL-standard function provides capabilities similar
9996     to <function>NVL</> and <function>IFNULL</>, which are used in some other
9997     database systems.
9998    </para>
9999   </sect2>
10000
10001   <sect2>
10002    <title><literal>NULLIF</></title>
10003
10004   <indexterm>
10005    <primary>NULLIF</primary>
10006   </indexterm>
10007
10008 <synopsis>
10009 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
10010 </synopsis>
10011
10012   <para>
10013    The <function>NULLIF</function> function returns a null value if
10014    <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
10015    otherwise it returns <replaceable>value1</replaceable>.
10016    This can be used to perform the inverse operation of the
10017    <function>COALESCE</function> example given above:
10018 <programlisting>
10019 SELECT NULLIF(value, '(none)') ...
10020 </programlisting>
10021   </para>
10022   <para>
10023    In this example, if <literal>value</literal> is <literal>(none)</>,
10024    null is returned, otherwise the value of <literal>value</literal>
10025    is returned.
10026   </para>
10027
10028   </sect2>
10029
10030   <sect2>
10031    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
10032
10033   <indexterm>
10034    <primary>GREATEST</primary>
10035   </indexterm>
10036   <indexterm>
10037    <primary>LEAST</primary>
10038   </indexterm>
10039
10040 <synopsis>
10041 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10042 </synopsis>
10043 <synopsis>
10044 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
10045 </synopsis>
10046
10047    <para>
10048     The <function>GREATEST</> and <function>LEAST</> functions select the
10049     largest or smallest value from a list of any number of expressions.
10050     The expressions must all be convertible to a common data type, which
10051     will be the type of the result
10052     (see <xref linkend="typeconv-union-case"> for details).  NULL values
10053     in the list are ignored.  The result will be NULL only if all the
10054     expressions evaluate to NULL.
10055    </para>
10056
10057    <para>
10058     Note that <function>GREATEST</> and <function>LEAST</> are not in
10059     the SQL standard, but are a common extension.  Some other databases
10060     make them return NULL if any argument is NULL, rather than only when
10061     all are NULL.
10062    </para>
10063   </sect2>
10064  </sect1>
10065
10066  <sect1 id="functions-array">
10067   <title>Array Functions and Operators</title>
10068
10069   <para>
10070    <xref linkend="array-operators-table"> shows the operators
10071    available for array types.
10072   </para>
10073
10074     <table id="array-operators-table">
10075      <title>Array Operators</title>
10076      <tgroup cols="4">
10077       <thead>
10078        <row>
10079         <entry>Operator</entry>
10080         <entry>Description</entry>
10081         <entry>Example</entry>
10082         <entry>Result</entry>
10083        </row>
10084       </thead>
10085       <tbody>
10086        <row>
10087         <entry> <literal>=</literal> </entry>
10088         <entry>equal</entry>
10089         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
10090         <entry><literal>t</literal></entry>
10091        </row>
10092
10093        <row>
10094         <entry> <literal>&lt;&gt;</literal> </entry>
10095         <entry>not equal</entry>
10096         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
10097         <entry><literal>t</literal></entry>
10098        </row>
10099
10100        <row>
10101         <entry> <literal>&lt;</literal> </entry>
10102         <entry>less than</entry>
10103         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
10104         <entry><literal>t</literal></entry>
10105        </row>
10106
10107        <row>
10108         <entry> <literal>&gt;</literal> </entry>
10109         <entry>greater than</entry>
10110         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
10111         <entry><literal>t</literal></entry>
10112        </row>
10113
10114        <row>
10115         <entry> <literal>&lt;=</literal> </entry>
10116         <entry>less than or equal</entry>
10117         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
10118         <entry><literal>t</literal></entry>
10119        </row>
10120
10121        <row>
10122         <entry> <literal>&gt;=</literal> </entry>
10123         <entry>greater than or equal</entry>
10124         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
10125         <entry><literal>t</literal></entry>
10126        </row>
10127
10128        <row>
10129         <entry> <literal>@&gt;</literal> </entry>
10130         <entry>contains</entry>
10131         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
10132         <entry><literal>t</literal></entry>
10133        </row>
10134
10135        <row>
10136         <entry> <literal>&lt;@</literal> </entry>
10137         <entry>is contained by</entry>
10138         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
10139         <entry><literal>t</literal></entry>
10140        </row>
10141
10142        <row>
10143         <entry> <literal>&amp;&amp;</literal> </entry>
10144         <entry>overlap (have elements in common)</entry>
10145         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
10146         <entry><literal>t</literal></entry>
10147        </row>
10148
10149        <row>
10150         <entry> <literal>||</literal> </entry>
10151         <entry>array-to-array concatenation</entry>
10152         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
10153         <entry><literal>{1,2,3,4,5,6}</literal></entry>
10154        </row>
10155
10156        <row>
10157         <entry> <literal>||</literal> </entry>
10158         <entry>array-to-array concatenation</entry>
10159         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
10160         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
10161        </row>
10162
10163        <row>
10164         <entry> <literal>||</literal> </entry>
10165         <entry>element-to-array concatenation</entry>
10166         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
10167         <entry><literal>{3,4,5,6}</literal></entry>
10168        </row>
10169
10170        <row>
10171         <entry> <literal>||</literal> </entry>
10172         <entry>array-to-element concatenation</entry>
10173         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
10174         <entry><literal>{4,5,6,7}</literal></entry>
10175        </row>
10176       </tbody>
10177      </tgroup>
10178     </table>
10179
10180   <para>
10181    Array comparisons compare the array contents element-by-element,
10182    using the default B-tree comparison function for the element data type.
10183    In multidimensional arrays the elements are visited in row-major order
10184    (last subscript varies most rapidly).
10185    If the contents of two arrays are equal but the dimensionality is
10186    different, the first difference in the dimensionality information
10187    determines the sort order.  (This is a change from versions of
10188    <productname>PostgreSQL</> prior to 8.2: older versions would claim
10189    that two arrays with the same contents were equal, even if the
10190    number of dimensions or subscript ranges were different.)
10191   </para>
10192
10193   <para>
10194    See <xref linkend="arrays"> for more details about array operator
10195    behavior.
10196   </para>
10197
10198   <para>
10199    <xref linkend="array-functions-table"> shows the functions
10200    available for use with array types. See <xref linkend="arrays">
10201    for more information  and examples of the use of these functions.
10202   </para>
10203
10204   <indexterm>
10205     <primary>array_append</primary>
10206   </indexterm>
10207   <indexterm>
10208     <primary>array_cat</primary>
10209   </indexterm>
10210   <indexterm>
10211     <primary>array_ndims</primary>
10212   </indexterm>
10213   <indexterm>
10214     <primary>array_dims</primary>
10215   </indexterm>
10216   <indexterm>
10217     <primary>array_fill</primary>
10218   </indexterm>
10219   <indexterm>
10220     <primary>array_length</primary>
10221   </indexterm>
10222   <indexterm>
10223     <primary>array_lower</primary>
10224   </indexterm>
10225   <indexterm>
10226     <primary>array_prepend</primary>
10227   </indexterm>
10228   <indexterm>
10229     <primary>array_to_string</primary>
10230   </indexterm>
10231  <indexterm>
10232     <primary>array_upper</primary>
10233   </indexterm>
10234   <indexterm>
10235     <primary>string_to_array</primary>
10236   </indexterm>
10237   <indexterm>
10238     <primary>unnest</primary>
10239   </indexterm>
10240
10241     <table id="array-functions-table">
10242      <title>Array Functions</title>
10243      <tgroup cols="5">
10244       <thead>
10245        <row>
10246         <entry>Function</entry>
10247         <entry>Return Type</entry>
10248         <entry>Description</entry>
10249         <entry>Example</entry>
10250         <entry>Result</entry>
10251        </row>
10252       </thead>
10253       <tbody>
10254        <row>
10255         <entry>
10256          <literal>
10257           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
10258          </literal>
10259         </entry>
10260         <entry><type>anyarray</type></entry>
10261         <entry>append an element to the end of an array</entry>
10262         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
10263         <entry><literal>{1,2,3}</literal></entry>
10264        </row>
10265        <row>
10266         <entry>
10267          <literal>
10268           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
10269          </literal>
10270         </entry>
10271         <entry><type>anyarray</type></entry>
10272         <entry>concatenate two arrays</entry>
10273         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
10274         <entry><literal>{1,2,3,4,5}</literal></entry>
10275        </row>
10276        <row>
10277         <entry>
10278          <literal>
10279           <function>array_ndims</function>(<type>anyarray</type>)
10280          </literal>
10281         </entry>
10282         <entry><type>int</type></entry>
10283         <entry>returns the number of dimensions of the array</entry>
10284         <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
10285         <entry><literal>2</literal></entry>
10286        </row>
10287        <row>
10288         <entry>
10289          <literal>
10290           <function>array_dims</function>(<type>anyarray</type>)
10291          </literal>
10292         </entry>
10293         <entry><type>text</type></entry>
10294         <entry>returns a text representation of array's dimensions</entry>
10295         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
10296         <entry><literal>[1:2][1:3]</literal></entry>
10297        </row>
10298        <row>
10299         <entry>
10300          <literal>
10301           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
10302           <optional>, <type>int[]</type></optional>)
10303          </literal>
10304         </entry>
10305         <entry><type>anyarray</type></entry>
10306         <entry>returns an array initialized with supplied value and
10307          dimensions, optionally with lower bounds other than 1</entry>
10308         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
10309         <entry><literal>[2:4]={7,7,7}</literal></entry>
10310        </row>
10311        <row>
10312         <entry>
10313          <literal>
10314           <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
10315          </literal>
10316         </entry>
10317         <entry><type>int</type></entry>
10318         <entry>returns the length of the requested array dimension</entry>
10319         <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
10320         <entry><literal>3</literal></entry>
10321        </row>
10322        <row>
10323         <entry>
10324          <literal>
10325           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
10326          </literal>
10327         </entry>
10328         <entry><type>int</type></entry>
10329         <entry>returns lower bound of the requested array dimension</entry>
10330         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
10331         <entry><literal>0</literal></entry>
10332        </row>
10333        <row>
10334         <entry>
10335          <literal>
10336           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
10337          </literal>
10338         </entry>
10339         <entry><type>anyarray</type></entry>
10340         <entry>append an element to the beginning of an array</entry>
10341         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
10342         <entry><literal>{1,2,3}</literal></entry>
10343        </row>
10344        <row>
10345         <entry>
10346          <literal>
10347           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type> <optional>, <type>text</type></optional>)
10348          </literal>
10349         </entry>
10350         <entry><type>text</type></entry>
10351         <entry>concatenates array elements using supplied delimiter and
10352          optional null string</entry>
10353         <entry><literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal></entry>
10354         <entry><literal>1,2,3,*,5</literal></entry>
10355        </row>
10356        <row>
10357         <entry>
10358          <literal>
10359           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
10360          </literal>
10361         </entry>
10362         <entry><type>int</type></entry>
10363         <entry>returns upper bound of the requested array dimension</entry>
10364         <entry><literal>array_upper(ARRAY[1,8,3,7], 1)</literal></entry>
10365         <entry><literal>4</literal></entry>
10366        </row>
10367        <row>
10368         <entry>
10369          <literal>
10370           <function>string_to_array</function>(<type>text</type>, <type>text</type> <optional>, <type>text</type></optional>)
10371          </literal>
10372         </entry>
10373         <entry><type>text[]</type></entry>
10374         <entry>splits string into array elements using supplied delimiter and
10375          optional null string</entry>
10376         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~', 'yy')</literal></entry>
10377         <entry><literal>{xx,NULL,zz}</literal></entry>
10378        </row>
10379        <row>
10380         <entry>
10381          <literal>
10382           <function>unnest</function>(<type>anyarray</type>)
10383          </literal>
10384         </entry>
10385         <entry><type>setof anyelement</type></entry>
10386         <entry>expand an array to a set of rows</entry>
10387         <entry><literal>unnest(ARRAY[1,2])</literal></entry>
10388         <entry><literallayout class="monospaced">1
10389 2</literallayout>(2 rows)</entry>
10390        </row>
10391       </tbody>
10392      </tgroup>
10393     </table>
10394
10395    <para>
10396     In <function>string_to_array</function>, if the delimiter parameter is
10397     NULL, each character in the input string will become a separate element in
10398     the resulting array.  If the delimiter is an empty string, then the entire
10399     input string is returned as a one-element array.  Otherwise the input
10400     string is split at each occurrence of the delimiter string.
10401    </para>
10402
10403    <para>
10404     In <function>string_to_array</function>, if the null-string parameter
10405     is omitted or NULL, none of the substrings of the input will be replaced
10406     by NULL.
10407     In <function>array_to_string</function>, if the null-string parameter
10408     is omitted or NULL, any null elements in the array are simply skipped
10409     and not represented in the output string.
10410    </para>
10411
10412    <note>
10413     <para>
10414      There are two differences in the behavior of <function>string_to_array</>
10415      from pre-9.1 versions of <productname>PostgreSQL</>.
10416      First, it will return an empty (zero-element) array rather than NULL when
10417      the input string is of zero length.  Second, if the delimiter string is
10418      NULL, the function splits the input into individual characters, rather
10419      than returning NULL as before.
10420     </para>
10421    </note>
10422
10423    <para>
10424     See also <xref linkend="functions-aggregate"> about the aggregate
10425     function <function>array_agg</function> for use with arrays.
10426    </para>
10427   </sect1>
10428
10429  <sect1 id="functions-aggregate">
10430   <title>Aggregate Functions</title>
10431
10432   <indexterm zone="functions-aggregate">
10433    <primary>aggregate function</primary>
10434    <secondary>built-in</secondary>
10435   </indexterm>
10436
10437   <para>
10438    <firstterm>Aggregate functions</firstterm> compute a single result
10439    from a set of input values.  The built-in aggregate functions
10440    are listed in
10441    <xref linkend="functions-aggregate-table"> and
10442    <xref linkend="functions-aggregate-statistics-table">.
10443    The special syntax considerations for aggregate
10444    functions are explained in <xref linkend="syntax-aggregates">.
10445    Consult <xref linkend="tutorial-agg"> for additional introductory
10446    information.
10447   </para>
10448
10449   <table id="functions-aggregate-table">
10450    <title>General-Purpose Aggregate Functions</title>
10451
10452    <tgroup cols="4">
10453     <thead>
10454      <row>
10455       <entry>Function</entry>
10456       <entry>Argument Type(s)</entry>
10457       <entry>Return Type</entry>
10458       <entry>Description</entry>
10459      </row>
10460     </thead>
10461
10462     <tbody>
10463      <row>
10464       <entry>
10465        <indexterm>
10466         <primary>array_agg</primary>
10467        </indexterm>
10468        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
10469       </entry>
10470       <entry>
10471        any
10472       </entry>
10473       <entry>
10474        array of the argument type
10475       </entry>
10476       <entry>input values, including nulls, concatenated into an array</entry>
10477      </row>
10478
10479      <row>
10480       <entry>
10481        <indexterm>
10482         <primary>average</primary>
10483        </indexterm>
10484        <indexterm>
10485         <primary>avg</primary>
10486        </indexterm>
10487        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
10488       </entry>
10489       <entry>
10490        <type>smallint</type>, <type>int</type>,
10491        <type>bigint</type>, <type>real</type>, <type>double
10492        precision</type>, <type>numeric</type>, or <type>interval</type>
10493       </entry>
10494       <entry>
10495        <type>numeric</type> for any integer-type argument,
10496        <type>double precision</type> for a floating-point argument,
10497        otherwise the same as the argument data type
10498       </entry>
10499       <entry>the average (arithmetic mean) of all input values</entry>
10500      </row>
10501
10502      <row>
10503       <entry>
10504        <indexterm>
10505         <primary>bit_and</primary>
10506        </indexterm>
10507        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
10508       </entry>
10509       <entry>
10510        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
10511        <type>bit</type>
10512       </entry>
10513       <entry>
10514         same as argument data type
10515       </entry>
10516       <entry>the bitwise AND of all non-null input values, or null if none</entry>
10517      </row>
10518
10519      <row>
10520       <entry>
10521        <indexterm>
10522         <primary>bit_or</primary>
10523        </indexterm>
10524        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
10525       </entry>
10526       <entry>
10527        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
10528        <type>bit</type>
10529       </entry>
10530       <entry>
10531         same as argument data type
10532       </entry>
10533       <entry>the bitwise OR of all non-null input values, or null if none</entry>
10534      </row>
10535
10536      <row>
10537       <entry>
10538        <indexterm>
10539         <primary>bool_and</primary>
10540        </indexterm>
10541        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
10542       </entry>
10543       <entry>
10544        <type>bool</type>
10545       </entry>
10546       <entry>
10547        <type>bool</type>
10548       </entry>
10549       <entry>true if all input values are true, otherwise false</entry>
10550      </row>
10551
10552      <row>
10553       <entry>
10554        <indexterm>
10555         <primary>bool_or</primary>
10556        </indexterm>
10557        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
10558       </entry>
10559       <entry>
10560        <type>bool</type>
10561       </entry>
10562       <entry>
10563        <type>bool</type>
10564       </entry>
10565       <entry>true if at least one input value is true, otherwise false</entry>
10566      </row>
10567
10568      <row>
10569       <entry>
10570        <indexterm>
10571         <primary>count</primary>
10572        </indexterm>
10573        <function>count(*)</function>
10574       </entry>
10575       <entry></entry>
10576       <entry><type>bigint</type></entry>
10577       <entry>number of input rows</entry>
10578      </row>
10579
10580      <row>
10581       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
10582       <entry>any</entry>
10583       <entry><type>bigint</type></entry>
10584       <entry>
10585        number of input rows for which the value of <replaceable
10586        class="parameter">expression</replaceable> is not null
10587       </entry>
10588      </row>
10589
10590      <row>
10591       <entry>
10592        <indexterm>
10593         <primary>every</primary>
10594        </indexterm>
10595        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
10596       </entry>
10597       <entry>
10598        <type>bool</type>
10599       </entry>
10600       <entry>
10601        <type>bool</type>
10602       </entry>
10603       <entry>equivalent to <function>bool_and</function></entry>
10604      </row>
10605
10606      <row>
10607       <entry>
10608        <indexterm>
10609         <primary>max</primary>
10610        </indexterm>
10611        <function>max(<replaceable class="parameter">expression</replaceable>)</function>
10612       </entry>
10613       <entry>any array, numeric, string, or date/time type</entry>
10614       <entry>same as argument type</entry>
10615       <entry>
10616        maximum value of <replaceable
10617        class="parameter">expression</replaceable> across all input
10618        values
10619       </entry>
10620      </row>
10621
10622      <row>
10623       <entry>
10624        <indexterm>
10625         <primary>min</primary>
10626        </indexterm>
10627        <function>min(<replaceable class="parameter">expression</replaceable>)</function>
10628       </entry>
10629       <entry>any array, numeric, string, or date/time type</entry>
10630       <entry>same as argument type</entry>
10631       <entry>
10632        minimum value of <replaceable
10633        class="parameter">expression</replaceable> across all input
10634        values
10635       </entry>
10636      </row>
10637
10638      <row>
10639       <entry>
10640        <indexterm>
10641         <primary>string_agg</primary>
10642        </indexterm>
10643        <function>
10644          string_agg(<replaceable class="parameter">expression</replaceable>,
10645                     <replaceable class="parameter">delimiter</replaceable>)
10646        </function>
10647       </entry>
10648       <entry>
10649        <type>text</type>, <type>text</type>
10650       </entry>
10651       <entry>
10652        <type>text</type>
10653       </entry>
10654       <entry>input values concatenated into a string, separated by delimiter</entry>
10655      </row>
10656
10657      <row>
10658       <entry>
10659        <indexterm>
10660         <primary>sum</primary>
10661        </indexterm>
10662        <function>sum(<replaceable class="parameter">expression</replaceable>)</function>
10663       </entry>
10664       <entry>
10665        <type>smallint</type>, <type>int</type>,
10666        <type>bigint</type>, <type>real</type>, <type>double
10667        precision</type>, <type>numeric</type>, or
10668        <type>interval</type>
10669       </entry>
10670       <entry>
10671        <type>bigint</type> for <type>smallint</type> or
10672        <type>int</type> arguments, <type>numeric</type> for
10673        <type>bigint</type> arguments, <type>double precision</type>
10674        for floating-point arguments, otherwise the same as the
10675        argument data type
10676       </entry>
10677       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
10678      </row>
10679
10680      <row>
10681       <entry>
10682        <indexterm>
10683         <primary>xmlagg</primary>
10684        </indexterm>
10685        <function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
10686       </entry>
10687       <entry>
10688        <type>xml</type>
10689       </entry>
10690       <entry>
10691        <type>xml</type>
10692       </entry>
10693       <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
10694      </row>
10695     </tbody>
10696    </tgroup>
10697   </table>
10698
10699   <para>
10700    It should be noted that except for <function>count</function>,
10701    these functions return a null value when no rows are selected.  In
10702    particular, <function>sum</function> of no rows returns null, not
10703    zero as one might expect, and <function>array_agg</function>
10704    returns null rather than an empty array when there are no input
10705    rows.  The <function>coalesce</function> function can be used to
10706    substitute zero or an empty array for null when necessary.
10707   </para>
10708
10709   <note>
10710     <indexterm>
10711       <primary>ANY</primary>
10712     </indexterm>
10713     <indexterm>
10714       <primary>SOME</primary>
10715     </indexterm>
10716     <para>
10717       Boolean aggregates <function>bool_and</function> and
10718       <function>bool_or</function> correspond to standard SQL aggregates
10719       <function>every</function> and <function>any</function> or
10720       <function>some</function>.
10721       As for <function>any</function> and <function>some</function>,
10722       it seems that there is an ambiguity built into the standard syntax:
10723 <programlisting>
10724 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
10725 </programlisting>
10726       Here <function>ANY</function> can be considered either as introducing
10727       a subquery, or as being an aggregate function, if the subquery
10728       returns one row with a Boolean value.
10729       Thus the standard name cannot be given to these aggregates.
10730     </para>
10731   </note>
10732
10733   <note>
10734    <para>
10735     Users accustomed to working with other SQL database management
10736     systems might be disappointed by the performance of the
10737     <function>count</function> aggregate when it is applied to the
10738     entire table. A query like:
10739 <programlisting>
10740 SELECT count(*) FROM sometable;
10741 </programlisting>
10742     will be executed by <productname>PostgreSQL</productname> using a
10743     sequential scan of the entire table.
10744    </para>
10745   </note>
10746
10747   <para>
10748    The aggregate functions <function>array_agg</function>,
10749    <function>string_agg</function>,
10750    and <function>xmlagg</function>, as well as similar user-defined
10751    aggregate functions, produce meaningfully different result values
10752    depending on the order of the input values.  This ordering is
10753    unspecified by default, but can be controlled by writing an
10754    <literal>ORDER BY</> clause within the aggregate call, as shown in
10755    <xref linkend="syntax-aggregates">.
10756    Alternatively, supplying the input values from a sorted subquery
10757    will usually work.  For example:
10758
10759 <screen><![CDATA[
10760 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
10761 ]]></screen>
10762
10763    But this syntax is not allowed in the SQL standard, and is
10764    not portable to other database systems.
10765   </para>
10766
10767   <para>
10768    <xref linkend="functions-aggregate-statistics-table"> shows
10769    aggregate functions typically used in statistical analysis.
10770    (These are separated out merely to avoid cluttering the listing
10771    of more-commonly-used aggregates.)  Where the description mentions
10772    <replaceable class="parameter">N</replaceable>, it means the
10773    number of input rows for which all the input expressions are non-null.
10774    In all cases, null is returned if the computation is meaningless,
10775    for example when <replaceable class="parameter">N</replaceable> is zero.
10776   </para>
10777
10778   <indexterm>
10779    <primary>statistics</primary>
10780   </indexterm>
10781   <indexterm>
10782    <primary>linear regression</primary>
10783   </indexterm>
10784
10785   <table id="functions-aggregate-statistics-table">
10786    <title>Aggregate Functions for Statistics</title>
10787
10788    <tgroup cols="4">
10789     <thead>
10790      <row>
10791       <entry>Function</entry>
10792       <entry>Argument Type</entry>
10793       <entry>Return Type</entry>
10794       <entry>Description</entry>
10795      </row>
10796     </thead>
10797
10798     <tbody>
10799
10800      <row>
10801       <entry>
10802        <indexterm>
10803         <primary>correlation</primary>
10804        </indexterm>
10805        <indexterm>
10806         <primary>corr</primary>
10807        </indexterm>
10808        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10809       </entry>
10810       <entry>
10811        <type>double precision</type>
10812       </entry>
10813       <entry>
10814        <type>double precision</type>
10815       </entry>
10816       <entry>correlation coefficient</entry>
10817      </row>
10818
10819      <row>
10820       <entry>
10821        <indexterm>
10822         <primary>covariance</primary>
10823         <secondary>population</secondary>
10824        </indexterm>
10825        <indexterm>
10826         <primary>covar_pop</primary>
10827        </indexterm>
10828        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10829       </entry>
10830       <entry>
10831        <type>double precision</type>
10832       </entry>
10833       <entry>
10834        <type>double precision</type>
10835       </entry>
10836       <entry>population covariance</entry>
10837      </row>
10838
10839      <row>
10840       <entry>
10841        <indexterm>
10842         <primary>covariance</primary>
10843         <secondary>sample</secondary>
10844        </indexterm>
10845        <indexterm>
10846         <primary>covar_samp</primary>
10847        </indexterm>
10848        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10849       </entry>
10850       <entry>
10851        <type>double precision</type>
10852       </entry>
10853       <entry>
10854        <type>double precision</type>
10855       </entry>
10856       <entry>sample covariance</entry>
10857      </row>
10858
10859      <row>
10860       <entry>
10861        <indexterm>
10862         <primary>regr_avgx</primary>
10863        </indexterm>
10864        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10865       </entry>
10866       <entry>
10867        <type>double precision</type>
10868       </entry>
10869       <entry>
10870        <type>double precision</type>
10871       </entry>
10872       <entry>average of the independent variable
10873       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
10874      </row>
10875
10876      <row>
10877       <entry>
10878        <indexterm>
10879         <primary>regr_avgy</primary>
10880        </indexterm>
10881        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10882       </entry>
10883       <entry>
10884        <type>double precision</type>
10885       </entry>
10886       <entry>
10887        <type>double precision</type>
10888       </entry>
10889       <entry>average of the dependent variable
10890       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
10891      </row>
10892
10893      <row>
10894       <entry>
10895        <indexterm>
10896         <primary>regr_count</primary>
10897        </indexterm>
10898        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10899       </entry>
10900       <entry>
10901        <type>double precision</type>
10902       </entry>
10903       <entry>
10904        <type>bigint</type>
10905       </entry>
10906       <entry>number of input rows in which both expressions are nonnull</entry>
10907      </row>
10908
10909      <row>
10910       <entry>
10911        <indexterm>
10912         <primary>regression intercept</primary>
10913        </indexterm>
10914        <indexterm>
10915         <primary>regr_intercept</primary>
10916        </indexterm>
10917        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10918       </entry>
10919       <entry>
10920        <type>double precision</type>
10921       </entry>
10922       <entry>
10923        <type>double precision</type>
10924       </entry>
10925       <entry>y-intercept of the least-squares-fit linear equation
10926       determined by the (<replaceable
10927       class="parameter">X</replaceable>, <replaceable
10928       class="parameter">Y</replaceable>) pairs</entry>
10929      </row>
10930
10931      <row>
10932       <entry>
10933        <indexterm>
10934         <primary>regr_r2</primary>
10935        </indexterm>
10936        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10937       </entry>
10938       <entry>
10939        <type>double precision</type>
10940       </entry>
10941       <entry>
10942        <type>double precision</type>
10943       </entry>
10944       <entry>square of the correlation coefficient</entry>
10945      </row>
10946
10947      <row>
10948       <entry>
10949        <indexterm>
10950         <primary>regression slope</primary>
10951        </indexterm>
10952        <indexterm>
10953         <primary>regr_slope</primary>
10954        </indexterm>
10955        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10956       </entry>
10957       <entry>
10958        <type>double precision</type>
10959       </entry>
10960       <entry>
10961        <type>double precision</type>
10962       </entry>
10963       <entry>slope of the least-squares-fit linear equation determined
10964       by the (<replaceable class="parameter">X</replaceable>,
10965       <replaceable class="parameter">Y</replaceable>) pairs</entry>
10966      </row>
10967
10968      <row>
10969       <entry>
10970        <indexterm>
10971         <primary>regr_sxx</primary>
10972        </indexterm>
10973        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10974       </entry>
10975       <entry>
10976        <type>double precision</type>
10977       </entry>
10978       <entry>
10979        <type>double precision</type>
10980       </entry>
10981       <entry><literal>sum(<replaceable
10982       class="parameter">X</replaceable>^2) - sum(<replaceable
10983       class="parameter">X</replaceable>)^2/<replaceable
10984       class="parameter">N</replaceable></literal> (<quote>sum of
10985       squares</quote> of the independent variable)</entry>
10986      </row>
10987
10988      <row>
10989       <entry>
10990        <indexterm>
10991         <primary>regr_sxy</primary>
10992        </indexterm>
10993        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10994       </entry>
10995       <entry>
10996        <type>double precision</type>
10997       </entry>
10998       <entry>
10999        <type>double precision</type>
11000       </entry>
11001       <entry><literal>sum(<replaceable
11002       class="parameter">X</replaceable>*<replaceable
11003       class="parameter">Y</replaceable>) - sum(<replaceable
11004       class="parameter">X</replaceable>) * sum(<replaceable
11005       class="parameter">Y</replaceable>)/<replaceable
11006       class="parameter">N</replaceable></literal> (<quote>sum of
11007       products</quote> of independent times dependent
11008       variable)</entry>
11009      </row>
11010
11011      <row>
11012       <entry>
11013        <indexterm>
11014         <primary>regr_syy</primary>
11015        </indexterm>
11016        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
11017       </entry>
11018       <entry>
11019        <type>double precision</type>
11020       </entry>
11021       <entry>
11022        <type>double precision</type>
11023       </entry>
11024       <entry><literal>sum(<replaceable
11025       class="parameter">Y</replaceable>^2) - sum(<replaceable
11026       class="parameter">Y</replaceable>)^2/<replaceable
11027       class="parameter">N</replaceable></literal> (<quote>sum of
11028       squares</quote> of the dependent variable)</entry>
11029      </row>
11030
11031      <row>
11032       <entry>
11033        <indexterm>
11034         <primary>standard deviation</primary>
11035        </indexterm>
11036        <indexterm>
11037         <primary>stddev</primary>
11038        </indexterm>
11039        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
11040       </entry>
11041       <entry>
11042        <type>smallint</type>, <type>int</type>,
11043        <type>bigint</type>, <type>real</type>, <type>double
11044        precision</type>, or <type>numeric</type>
11045       </entry>
11046       <entry>
11047        <type>double precision</type> for floating-point arguments,
11048        otherwise <type>numeric</type>
11049       </entry>
11050       <entry>historical alias for <function>stddev_samp</function></entry>
11051      </row>
11052
11053      <row>
11054       <entry>
11055        <indexterm>
11056         <primary>standard deviation</primary>
11057         <secondary>population</secondary>
11058        </indexterm>
11059        <indexterm>
11060         <primary>stddev_pop</primary>
11061        </indexterm>
11062        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
11063       </entry>
11064       <entry>
11065        <type>smallint</type>, <type>int</type>,
11066        <type>bigint</type>, <type>real</type>, <type>double
11067        precision</type>, or <type>numeric</type>
11068       </entry>
11069       <entry>
11070        <type>double precision</type> for floating-point arguments,
11071        otherwise <type>numeric</type>
11072       </entry>
11073       <entry>population standard deviation of the input values</entry>
11074      </row>
11075
11076      <row>
11077       <entry>
11078        <indexterm>
11079         <primary>standard deviation</primary>
11080         <secondary>sample</secondary>
11081        </indexterm>
11082        <indexterm>
11083         <primary>stddev_samp</primary>
11084        </indexterm>
11085        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
11086       </entry>
11087       <entry>
11088        <type>smallint</type>, <type>int</type>,
11089        <type>bigint</type>, <type>real</type>, <type>double
11090        precision</type>, or <type>numeric</type>
11091       </entry>
11092       <entry>
11093        <type>double precision</type> for floating-point arguments,
11094        otherwise <type>numeric</type>
11095       </entry>
11096       <entry>sample standard deviation of the input values</entry>
11097      </row>
11098
11099      <row>
11100       <entry>
11101        <indexterm>
11102         <primary>variance</primary>
11103        </indexterm>
11104        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
11105       </entry>
11106       <entry>
11107        <type>smallint</type>, <type>int</type>,
11108        <type>bigint</type>, <type>real</type>, <type>double
11109        precision</type>, or <type>numeric</type>
11110       </entry>
11111       <entry>
11112        <type>double precision</type> for floating-point arguments,
11113        otherwise <type>numeric</type>
11114       </entry>
11115       <entry>historical alias for <function>var_samp</function></entry>
11116      </row>
11117
11118      <row>
11119       <entry>
11120        <indexterm>
11121         <primary>variance</primary>
11122         <secondary>population</secondary>
11123        </indexterm>
11124        <indexterm>
11125         <primary>var_pop</primary>
11126        </indexterm>
11127        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
11128       </entry>
11129       <entry>
11130        <type>smallint</type>, <type>int</type>,
11131        <type>bigint</type>, <type>real</type>, <type>double
11132        precision</type>, or <type>numeric</type>
11133       </entry>
11134       <entry>
11135        <type>double precision</type> for floating-point arguments,
11136        otherwise <type>numeric</type>
11137       </entry>
11138       <entry>population variance of the input values (square of the population standard deviation)</entry>
11139      </row>
11140
11141      <row>
11142       <entry>
11143        <indexterm>
11144         <primary>variance</primary>
11145         <secondary>sample</secondary>
11146        </indexterm>
11147        <indexterm>
11148         <primary>var_samp</primary>
11149        </indexterm>
11150        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
11151       </entry>
11152       <entry>
11153        <type>smallint</type>, <type>int</type>,
11154        <type>bigint</type>, <type>real</type>, <type>double
11155        precision</type>, or <type>numeric</type>
11156       </entry>
11157       <entry>
11158        <type>double precision</type> for floating-point arguments,
11159        otherwise <type>numeric</type>
11160       </entry>
11161       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
11162      </row>
11163     </tbody>
11164    </tgroup>
11165   </table>
11166
11167  </sect1>
11168
11169  <sect1 id="functions-window">
11170   <title>Window Functions</title>
11171
11172   <indexterm zone="functions-window">
11173    <primary>window function</primary>
11174    <secondary>built-in</secondary>
11175   </indexterm>
11176
11177   <para>
11178    <firstterm>Window functions</firstterm> provide the ability to perform
11179    calculations across sets of rows that are related to the current query
11180    row.  See <xref linkend="tutorial-window"> for an introduction to this
11181    feature.
11182   </para>
11183
11184   <para>
11185    The built-in window functions are listed in
11186    <xref linkend="functions-window-table">.  Note that these functions
11187    <emphasis>must</> be invoked using window function syntax; that is an
11188    <literal>OVER</> clause is required.
11189   </para>
11190
11191   <para>
11192    In addition to these functions, any built-in or user-defined aggregate
11193    function can be used as a window function (see
11194    <xref linkend="functions-aggregate"> for a list of the built-in aggregates).
11195    Aggregate functions act as window functions only when an <literal>OVER</>
11196    clause follows the call; otherwise they act as regular aggregates.
11197   </para>
11198
11199   <table id="functions-window-table">
11200    <title>General-Purpose Window Functions</title>
11201
11202    <tgroup cols="3">
11203     <thead>
11204      <row>
11205       <entry>Function</entry>
11206       <entry>Return Type</entry>
11207       <entry>Description</entry>
11208      </row>
11209     </thead>
11210
11211     <tbody>
11212      <row>
11213       <entry>
11214        <indexterm>
11215         <primary>row_number</primary>
11216        </indexterm>
11217        <function>row_number()</function>
11218       </entry>
11219       <entry>
11220        <type>bigint</type>
11221       </entry>
11222       <entry>number of the current row within its partition, counting from 1</entry>
11223      </row>
11224
11225      <row>
11226       <entry>
11227        <indexterm>
11228         <primary>rank</primary>
11229        </indexterm>
11230        <function>rank()</function>
11231       </entry>
11232       <entry>
11233        <type>bigint</type>
11234       </entry>
11235       <entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
11236      </row>
11237
11238      <row>
11239       <entry>
11240        <indexterm>
11241         <primary>dense_rank</primary>
11242        </indexterm>
11243        <function>dense_rank()</function>
11244       </entry>
11245       <entry>
11246        <type>bigint</type>
11247       </entry>
11248       <entry>rank of the current row without gaps; this function counts peer groups</entry>
11249      </row>
11250
11251      <row>
11252       <entry>
11253        <indexterm>
11254         <primary>percent_rank</primary>
11255        </indexterm>
11256        <function>percent_rank()</function>
11257       </entry>
11258       <entry>
11259        <type>double precision</type>
11260       </entry>
11261       <entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
11262      </row>
11263
11264      <row>
11265       <entry>
11266        <indexterm>
11267         <primary>cume_dist</primary>
11268        </indexterm>
11269        <function>cume_dist()</function>
11270       </entry>
11271       <entry>
11272        <type>double precision</type>
11273       </entry>
11274       <entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
11275      </row>
11276
11277      <row>
11278       <entry>
11279        <indexterm>
11280         <primary>ntile</primary>
11281        </indexterm>
11282        <function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</>)</function>
11283       </entry>
11284       <entry>
11285        <type>integer</type>
11286       </entry>
11287       <entry>integer ranging from 1 to the argument value, dividing the
11288        partition as equally as possible</entry>
11289      </row>
11290
11291      <row>
11292       <entry>
11293        <indexterm>
11294         <primary>lag</primary>
11295        </indexterm>
11296        <function>
11297          lag(<replaceable class="parameter">value</replaceable> <type>any</>
11298              [, <replaceable class="parameter">offset</replaceable> <type>integer</>
11299              [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
11300        </function>
11301       </entry>
11302       <entry>
11303        <type>same type as <replaceable class="parameter">value</replaceable></type>
11304       </entry>
11305       <entry>
11306        returns <replaceable class="parameter">value</replaceable> evaluated at
11307        the row that is <replaceable class="parameter">offset</replaceable>
11308        rows before the current row within the partition; if there is no such
11309        row, instead return <replaceable class="parameter">default</replaceable>.
11310        Both <replaceable class="parameter">offset</replaceable> and
11311        <replaceable class="parameter">default</replaceable> are evaluated
11312        with respect to the current row.  If omitted,
11313        <replaceable class="parameter">offset</replaceable> defaults to 1 and
11314        <replaceable class="parameter">default</replaceable> to null
11315       </entry>
11316      </row>
11317
11318      <row>
11319       <entry>
11320        <indexterm>
11321         <primary>lead</primary>
11322        </indexterm>
11323        <function>
11324          lead(<replaceable class="parameter">value</replaceable> <type>any</>
11325               [, <replaceable class="parameter">offset</replaceable> <type>integer</>
11326               [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
11327        </function>
11328       </entry>
11329       <entry>
11330        <type>same type as <replaceable class="parameter">value</replaceable></type>
11331       </entry>
11332       <entry>
11333        returns <replaceable class="parameter">value</replaceable> evaluated at
11334        the row that is <replaceable class="parameter">offset</replaceable>
11335        rows after the current row within the partition; if there is no such
11336        row, instead return <replaceable class="parameter">default</replaceable>.
11337        Both <replaceable class="parameter">offset</replaceable> and
11338        <replaceable class="parameter">default</replaceable> are evaluated
11339        with respect to the current row.  If omitted,
11340        <replaceable class="parameter">offset</replaceable> defaults to 1 and
11341        <replaceable class="parameter">default</replaceable> to null
11342       </entry>
11343      </row>
11344
11345      <row>
11346       <entry>
11347        <indexterm>
11348         <primary>first_value</primary>
11349        </indexterm>
11350        <function>first_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
11351       </entry>
11352       <entry>
11353        <type>same type as <replaceable class="parameter">value</replaceable></type>
11354       </entry>
11355       <entry>
11356        returns <replaceable class="parameter">value</replaceable> evaluated
11357        at the row that is the first row of the window frame
11358       </entry>
11359      </row>
11360
11361      <row>
11362       <entry>
11363        <indexterm>
11364         <primary>last_value</primary>
11365        </indexterm>
11366        <function>last_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
11367       </entry>
11368       <entry>
11369        <type>same type as <replaceable class="parameter">value</replaceable></type>
11370       </entry>
11371       <entry>
11372        returns <replaceable class="parameter">value</replaceable> evaluated
11373        at the row that is the last row of the window frame
11374       </entry>
11375      </row>
11376
11377      <row>
11378       <entry>
11379        <indexterm>
11380         <primary>nth_value</primary>
11381        </indexterm>
11382        <function>
11383          nth_value(<replaceable class="parameter">value</replaceable> <type>any</>, <replaceable class="parameter">nth</replaceable> <type>integer</>)
11384        </function>
11385       </entry>
11386       <entry>
11387        <type>same type as <replaceable class="parameter">value</replaceable></type>
11388       </entry>
11389       <entry>
11390        returns <replaceable class="parameter">value</replaceable> evaluated
11391        at the row that is the <replaceable class="parameter">nth</replaceable>
11392        row of the window frame (counting from 1); null if no such row
11393       </entry>
11394      </row>
11395     </tbody>
11396    </tgroup>
11397   </table>
11398
11399   <para>
11400    All of the functions listed in
11401    <xref linkend="functions-window-table"> depend on the sort ordering
11402    specified by the <literal>ORDER BY</> clause of the associated window
11403    definition.  Rows that are not distinct in the <literal>ORDER BY</>
11404    ordering are said to be <firstterm>peers</>; the four ranking functions
11405    are defined so that they give the same answer for any two peer rows.
11406   </para>
11407
11408   <para>
11409    Note that <function>first_value</>, <function>last_value</>, and
11410    <function>nth_value</> consider only the rows within the <quote>window
11411    frame</>, which by default contains the rows from the start of the
11412    partition through the last peer of the current row.  This is
11413    likely to give unhelpful results for <function>last_value</> and
11414    sometimes also <function>nth_value</>.  You can redefine the frame by
11415    adding a suitable frame specification (<literal>RANGE</> or
11416    <literal>ROWS</>) to the <literal>OVER</> clause.
11417    See <xref linkend="syntax-window-functions"> for more information
11418    about frame specifications.
11419   </para>
11420
11421   <para>
11422    When an aggregate function is used as a window function, it aggregates
11423    over the rows within the current row's window frame.
11424    An aggregate used with <literal>ORDER BY</> and the default window frame
11425    definition produces a <quote>running sum</> type of behavior, which may or
11426    may not be what's wanted.  To obtain
11427    aggregation over the whole partition, omit <literal>ORDER BY</> or use
11428    <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
11429    Other frame specifications can be used to obtain other effects.
11430   </para>
11431
11432   <note>
11433    <para>
11434     The SQL standard defines a <literal>RESPECT NULLS</> or
11435     <literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
11436     <function>first_value</>, <function>last_value</>, and
11437     <function>nth_value</>.  This is not implemented in
11438     <productname>PostgreSQL</productname>: the behavior is always the
11439     same as the standard's default, namely <literal>RESPECT NULLS</>.
11440     Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
11441     option for <function>nth_value</> is not implemented: only the
11442     default <literal>FROM FIRST</> behavior is supported.  (You can achieve
11443     the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
11444     ordering.)
11445    </para>
11446   </note>
11447
11448  </sect1>
11449
11450  <sect1 id="functions-subquery">
11451   <title>Subquery Expressions</title>
11452
11453   <indexterm>
11454    <primary>EXISTS</primary>
11455   </indexterm>
11456
11457   <indexterm>
11458    <primary>IN</primary>
11459   </indexterm>
11460
11461   <indexterm>
11462    <primary>NOT IN</primary>
11463   </indexterm>
11464
11465   <indexterm>
11466    <primary>ANY</primary>
11467   </indexterm>
11468
11469   <indexterm>
11470    <primary>ALL</primary>
11471   </indexterm>
11472
11473   <indexterm>
11474    <primary>SOME</primary>
11475   </indexterm>
11476
11477   <indexterm>
11478    <primary>subquery</primary>
11479   </indexterm>
11480
11481   <para>
11482    This section describes the <acronym>SQL</acronym>-compliant subquery
11483    expressions available in <productname>PostgreSQL</productname>.
11484    All of the expression forms documented in this section return
11485    Boolean (true/false) results.
11486   </para>
11487
11488   <sect2>
11489    <title><literal>EXISTS</literal></title>
11490
11491 <synopsis>
11492 EXISTS (<replaceable>subquery</replaceable>)
11493 </synopsis>
11494
11495   <para>
11496    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
11497    or <firstterm>subquery</firstterm>.  The
11498    subquery is evaluated to determine whether it returns any rows.
11499    If it returns at least one row, the result of <token>EXISTS</token> is
11500    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
11501    is <quote>false</>.
11502   </para>
11503
11504   <para>
11505    The subquery can refer to variables from the surrounding query,
11506    which will act as constants during any one evaluation of the subquery.
11507   </para>
11508
11509   <para>
11510    The subquery will generally only be executed long enough to determine
11511    whether at least one row is returned, not all the way to completion.
11512    It is unwise to write a subquery that has side effects (such as
11513    calling sequence functions); whether the side effects occur
11514    might be unpredictable.
11515   </para>
11516
11517   <para>
11518    Since the result depends only on whether any rows are returned,
11519    and not on the contents of those rows, the output list of the
11520    subquery is normally unimportant.  A common coding convention is
11521    to write all <literal>EXISTS</> tests in the form
11522    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
11523    this rule however, such as subqueries that use <token>INTERSECT</token>.
11524   </para>
11525
11526   <para>
11527    This simple example is like an inner join on <literal>col2</>, but
11528    it produces at most one output row for each <literal>tab1</> row,
11529    even if there are several matching <literal>tab2</> rows:
11530 <screen>
11531 SELECT col1
11532 FROM tab1
11533 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
11534 </screen>
11535   </para>
11536   </sect2>
11537
11538   <sect2>
11539    <title><literal>IN</literal></title>
11540
11541 <synopsis>
11542 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
11543 </synopsis>
11544
11545   <para>
11546    The right-hand side is a parenthesized
11547    subquery, which must return exactly one column.  The left-hand expression
11548    is evaluated and compared to each row of the subquery result.
11549    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
11550    The result is <quote>false</> if no equal row is found (including the
11551    case where the subquery returns no rows).
11552   </para>
11553
11554   <para>
11555    Note that if the left-hand expression yields null, or if there are
11556    no equal right-hand values and at least one right-hand row yields
11557    null, the result of the <token>IN</token> construct will be null, not false.
11558    This is in accordance with SQL's normal rules for Boolean combinations
11559    of null values.
11560   </para>
11561
11562   <para>
11563    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
11564    be evaluated completely.
11565   </para>
11566
11567 <synopsis>
11568 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
11569 </synopsis>
11570
11571   <para>
11572    The left-hand side of this form of <token>IN</token> is a row constructor,
11573    as described in <xref linkend="sql-syntax-row-constructors">.
11574    The right-hand side is a parenthesized
11575    subquery, which must return exactly as many columns as there are
11576    expressions in the left-hand row.  The left-hand expressions are
11577    evaluated and compared row-wise to each row of the subquery result.
11578    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
11579    The result is <quote>false</> if no equal row is found (including the
11580    case where the subquery returns no rows).
11581   </para>
11582
11583   <para>
11584    As usual, null values in the rows are combined per
11585    the normal rules of SQL Boolean expressions.  Two rows are considered
11586    equal if all their corresponding members are non-null and equal; the rows
11587    are unequal if any corresponding members are non-null and unequal;
11588    otherwise the result of that row comparison is unknown (null).
11589    If all the per-row results are either unequal or null, with at least one
11590    null, then the result of <token>IN</token> is null.
11591   </para>
11592   </sect2>
11593
11594   <sect2>
11595    <title><literal>NOT IN</literal></title>
11596
11597 <synopsis>
11598 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
11599 </synopsis>
11600
11601   <para>
11602    The right-hand side is a parenthesized
11603    subquery, which must return exactly one column.  The left-hand expression
11604    is evaluated and compared to each row of the subquery result.
11605    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
11606    are found (including the case where the subquery returns no rows).
11607    The result is <quote>false</> if any equal row is found.
11608   </para>
11609
11610   <para>
11611    Note that if the left-hand expression yields null, or if there are
11612    no equal right-hand values and at least one right-hand row yields
11613    null, the result of the <token>NOT IN</token> construct will be null, not true.
11614    This is in accordance with SQL's normal rules for Boolean combinations
11615    of null values.
11616   </para>
11617
11618   <para>
11619    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
11620    be evaluated completely.
11621   </para>
11622
11623 <synopsis>
11624 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
11625 </synopsis>
11626
11627   <para>
11628    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
11629    as described in <xref linkend="sql-syntax-row-constructors">.
11630    The right-hand side is a parenthesized
11631    subquery, which must return exactly as many columns as there are
11632    expressions in the left-hand row.  The left-hand expressions are
11633    evaluated and compared row-wise to each row of the subquery result.
11634    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
11635    are found (including the case where the subquery returns no rows).
11636    The result is <quote>false</> if any equal row is found.
11637   </para>
11638
11639   <para>
11640    As usual, null values in the rows are combined per
11641    the normal rules of SQL Boolean expressions.  Two rows are considered
11642    equal if all their corresponding members are non-null and equal; the rows
11643    are unequal if any corresponding members are non-null and unequal;
11644    otherwise the result of that row comparison is unknown (null).
11645    If all the per-row results are either unequal or null, with at least one
11646    null, then the result of <token>NOT IN</token> is null.
11647   </para>
11648   </sect2>
11649
11650   <sect2>
11651    <title><literal>ANY</literal>/<literal>SOME</literal></title>
11652
11653 <synopsis>
11654 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
11655 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
11656 </synopsis>
11657
11658   <para>
11659    The right-hand side is a parenthesized
11660    subquery, which must return exactly one column.  The left-hand expression
11661    is evaluated and compared to each row of the subquery result using the
11662    given <replaceable>operator</replaceable>, which must yield a Boolean
11663    result.
11664    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
11665    The result is <quote>false</> if no true result is found (including the
11666    case where the subquery returns no rows).
11667   </para>
11668
11669   <para>
11670    <token>SOME</token> is a synonym for <token>ANY</token>.
11671    <token>IN</token> is equivalent to <literal>= ANY</literal>.
11672   </para>
11673
11674   <para>
11675    Note that if there are no successes and at least one right-hand row yields
11676    null for the operator's result, the result of the <token>ANY</token> construct
11677    will be null, not false.
11678    This is in accordance with SQL's normal rules for Boolean combinations
11679    of null values.
11680   </para>
11681
11682   <para>
11683    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
11684    be evaluated completely.
11685   </para>
11686
11687 <synopsis>
11688 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
11689 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
11690 </synopsis>
11691
11692   <para>
11693    The left-hand side of this form of <token>ANY</token> is a row constructor,
11694    as described in <xref linkend="sql-syntax-row-constructors">.
11695    The right-hand side is a parenthesized
11696    subquery, which must return exactly as many columns as there are
11697    expressions in the left-hand row.  The left-hand expressions are
11698    evaluated and compared row-wise to each row of the subquery result,
11699    using the given <replaceable>operator</replaceable>.
11700    The result of <token>ANY</token> is <quote>true</> if the comparison
11701    returns true for any subquery row.
11702    The result is <quote>false</> if the comparison returns false for every
11703    subquery row (including the case where the subquery returns no
11704    rows).
11705    The result is NULL if the comparison does not return true for any row,
11706    and it returns NULL for at least one row.
11707   </para>
11708
11709   <para>
11710    See <xref linkend="row-wise-comparison"> for details about the meaning
11711    of a row-wise comparison.
11712   </para>
11713   </sect2>
11714
11715   <sect2>
11716    <title><literal>ALL</literal></title>
11717
11718 <synopsis>
11719 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
11720 </synopsis>
11721
11722   <para>
11723    The right-hand side is a parenthesized
11724    subquery, which must return exactly one column.  The left-hand expression
11725    is evaluated and compared to each row of the subquery result using the
11726    given <replaceable>operator</replaceable>, which must yield a Boolean
11727    result.
11728    The result of <token>ALL</token> is <quote>true</> if all rows yield true
11729    (including the case where the subquery returns no rows).
11730    The result is <quote>false</> if any false result is found.
11731    The result is NULL if the comparison does not return false for any row,
11732    and it returns NULL for at least one row.
11733   </para>
11734
11735   <para>
11736    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
11737   </para>
11738
11739   <para>
11740    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
11741    be evaluated completely.
11742   </para>
11743
11744 <synopsis>
11745 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
11746 </synopsis>
11747
11748   <para>
11749    The left-hand side of this form of <token>ALL</token> is a row constructor,
11750    as described in <xref linkend="sql-syntax-row-constructors">.
11751    The right-hand side is a parenthesized
11752    subquery, which must return exactly as many columns as there are
11753    expressions in the left-hand row.  The left-hand expressions are
11754    evaluated and compared row-wise to each row of the subquery result,
11755    using the given <replaceable>operator</replaceable>.
11756    The result of <token>ALL</token> is <quote>true</> if the comparison
11757    returns true for all subquery rows (including the
11758    case where the subquery returns no rows).
11759    The result is <quote>false</> if the comparison returns false for any
11760    subquery row.
11761    The result is NULL if the comparison does not return false for any
11762    subquery row, and it returns NULL for at least one row.
11763   </para>
11764
11765   <para>
11766    See <xref linkend="row-wise-comparison"> for details about the meaning
11767    of a row-wise comparison.
11768   </para>
11769   </sect2>
11770
11771   <sect2>
11772    <title>Row-wise Comparison</title>
11773
11774    <indexterm zone="functions-subquery">
11775     <primary>comparison</primary>
11776     <secondary>subquery result row</secondary>
11777    </indexterm>
11778
11779 <synopsis>
11780 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
11781 </synopsis>
11782
11783   <para>
11784    The left-hand side is a row constructor,
11785    as described in <xref linkend="sql-syntax-row-constructors">.
11786    The right-hand side is a parenthesized subquery, which must return exactly
11787    as many columns as there are expressions in the left-hand row. Furthermore,
11788    the subquery cannot return more than one row.  (If it returns zero rows,
11789    the result is taken to be null.)  The left-hand side is evaluated and
11790    compared row-wise to the single subquery result row.
11791   </para>
11792
11793   <para>
11794    See <xref linkend="row-wise-comparison"> for details about the meaning
11795    of a row-wise comparison.
11796   </para>
11797   </sect2>
11798  </sect1>
11799
11800
11801  <sect1 id="functions-comparisons">
11802   <title>Row and Array Comparisons</title>
11803
11804   <indexterm>
11805    <primary>IN</primary>
11806   </indexterm>
11807
11808   <indexterm>
11809    <primary>NOT IN</primary>
11810   </indexterm>
11811
11812   <indexterm>
11813    <primary>ANY</primary>
11814   </indexterm>
11815
11816   <indexterm>
11817    <primary>ALL</primary>
11818   </indexterm>
11819
11820   <indexterm>
11821    <primary>SOME</primary>
11822   </indexterm>
11823
11824   <indexterm>
11825    <primary>row-wise comparison</primary>
11826   </indexterm>
11827
11828   <indexterm>
11829    <primary>comparison</primary>
11830    <secondary>row-wise</secondary>
11831   </indexterm>
11832
11833   <indexterm>
11834    <primary>IS DISTINCT FROM</primary>
11835   </indexterm>
11836
11837   <indexterm>
11838    <primary>IS NOT DISTINCT FROM</primary>
11839   </indexterm>
11840
11841   <para>
11842    This section describes several specialized constructs for making
11843    multiple comparisons between groups of values.  These forms are
11844    syntactically related to the subquery forms of the previous section,
11845    but do not involve subqueries.
11846    The forms involving array subexpressions are
11847    <productname>PostgreSQL</productname> extensions; the rest are
11848    <acronym>SQL</acronym>-compliant.
11849    All of the expression forms documented in this section return
11850    Boolean (true/false) results.
11851   </para>
11852
11853   <sect2>
11854    <title><literal>IN</literal></title>
11855
11856 <synopsis>
11857 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
11858 </synopsis>
11859
11860   <para>
11861    The right-hand side is a parenthesized list
11862    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
11863    result is equal to any of the right-hand expressions.  This is a shorthand
11864    notation for
11865
11866 <synopsis>
11867 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
11868 OR
11869 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
11870 OR
11871 ...
11872 </synopsis>
11873   </para>
11874
11875   <para>
11876    Note that if the left-hand expression yields null, or if there are
11877    no equal right-hand values and at least one right-hand expression yields
11878    null, the result of the <token>IN</token> construct will be null, not false.
11879    This is in accordance with SQL's normal rules for Boolean combinations
11880    of null values.
11881   </para>
11882   </sect2>
11883
11884   <sect2>
11885    <title><literal>NOT IN</literal></title>
11886
11887 <synopsis>
11888 <replaceable>expression</replaceable> NOT 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</quote> if the left-hand expression's
11894    result is unequal to all of the right-hand expressions.  This is a shorthand
11895    notation for
11896
11897 <synopsis>
11898 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
11899 AND
11900 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
11901 AND
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>NOT IN</token> construct will be null, not true
11910    as one might naively expect.
11911    This is in accordance with SQL's normal rules for Boolean combinations
11912    of null values.
11913   </para>
11914
11915   <tip>
11916   <para>
11917    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
11918    cases.  However, null values are much more likely to trip up the novice when
11919    working with <token>NOT IN</token> than when working with <token>IN</token>.
11920    It is best to express your condition positively if possible.
11921   </para>
11922   </tip>
11923   </sect2>
11924
11925   <sect2>
11926    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
11927
11928 <synopsis>
11929 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
11930 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
11931 </synopsis>
11932
11933   <para>
11934    The right-hand side is a parenthesized expression, which must yield an
11935    array value.
11936    The left-hand expression
11937    is evaluated and compared to each element of the array using the
11938    given <replaceable>operator</replaceable>, which must yield a Boolean
11939    result.
11940    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
11941    The result is <quote>false</> if no true result is found (including the
11942    case where the array has zero elements).
11943   </para>
11944
11945   <para>
11946    If the array expression yields a null array, the result of
11947    <token>ANY</token> will be null.  If the left-hand expression yields null,
11948    the result of <token>ANY</token> is ordinarily null (though a non-strict
11949    comparison operator could possibly yield a different result).
11950    Also, if the right-hand array contains any null elements and no true
11951    comparison result is obtained, the result of <token>ANY</token>
11952    will be null, not false (again, assuming a strict comparison operator).
11953    This is in accordance with SQL's normal rules for Boolean combinations
11954    of null values.
11955   </para>
11956
11957   <para>
11958    <token>SOME</token> is a synonym for <token>ANY</token>.
11959   </para>
11960   </sect2>
11961
11962   <sect2>
11963    <title><literal>ALL</literal> (array)</title>
11964
11965 <synopsis>
11966 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
11967 </synopsis>
11968
11969   <para>
11970    The right-hand side is a parenthesized expression, which must yield an
11971    array value.
11972    The left-hand expression
11973    is evaluated and compared to each element of the array using the
11974    given <replaceable>operator</replaceable>, which must yield a Boolean
11975    result.
11976    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
11977    (including the case where the array has zero elements).
11978    The result is <quote>false</> if any false result is found.
11979   </para>
11980
11981   <para>
11982    If the array expression yields a null array, the result of
11983    <token>ALL</token> will be null.  If the left-hand expression yields null,
11984    the result of <token>ALL</token> is ordinarily null (though a non-strict
11985    comparison operator could possibly yield a different result).
11986    Also, if the right-hand array contains any null elements and no false
11987    comparison result is obtained, the result of <token>ALL</token>
11988    will be null, not true (again, assuming a strict comparison operator).
11989    This is in accordance with SQL's normal rules for Boolean combinations
11990    of null values.
11991   </para>
11992   </sect2>
11993
11994   <sect2 id="row-wise-comparison">
11995    <title>Row-wise Comparison</title>
11996
11997 <synopsis>
11998 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
11999 </synopsis>
12000
12001   <para>
12002    Each side is a row constructor,
12003    as described in <xref linkend="sql-syntax-row-constructors">.
12004    The two row values must have the same number of fields.
12005    Each side is evaluated and they are compared row-wise.  Row comparisons
12006    are allowed when the <replaceable>operator</replaceable> is
12007    <literal>=</>,
12008    <literal>&lt;&gt;</>,
12009    <literal>&lt;</>,
12010    <literal>&lt;=</>,
12011    <literal>&gt;</> or
12012    <literal>&gt;=</>,
12013    or has semantics similar to one of these.  (To be specific, an operator
12014    can be a row comparison operator if it is a member of a B-tree operator
12015    class, or is the negator of the <literal>=</> member of a B-tree operator
12016    class.)
12017   </para>
12018
12019   <para>
12020    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
12021    from the others.  Two rows are considered
12022    equal if all their corresponding members are non-null and equal; the rows
12023    are unequal if any corresponding members are non-null and unequal;
12024    otherwise the result of the row comparison is unknown (null).
12025   </para>
12026
12027   <para>
12028    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
12029    <literal>&gt;=</> cases, the row elements are compared left-to-right,
12030    stopping as soon as an unequal or null pair of elements is found.
12031    If either of this pair of elements is null, the result of the
12032    row comparison is unknown (null); otherwise comparison of this pair
12033    of elements determines the result.  For example,
12034    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
12035    yields true, not null, because the third pair of elements are not
12036    considered.
12037   </para>
12038
12039   <note>
12040    <para>
12041     Prior to <productname>PostgreSQL</productname> 8.2, the
12042     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
12043     cases were not handled per SQL specification.  A comparison like
12044     <literal>ROW(a,b) &lt; ROW(c,d)</>
12045     was implemented as
12046     <literal>a &lt; c AND b &lt; d</>
12047     whereas the correct behavior is equivalent to
12048     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
12049    </para>
12050   </note>
12051
12052 <synopsis>
12053 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
12054 </synopsis>
12055
12056   <para>
12057    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
12058    but it does not yield null for null inputs.  Instead, any null value is
12059    considered unequal to (distinct from) any non-null value, and any two
12060    nulls are considered equal (not distinct).  Thus the result will
12061    either be true or false, never null.
12062   </para>
12063
12064 <synopsis>
12065 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
12066 </synopsis>
12067
12068   <para>
12069    This construct is similar to a <literal>=</literal> row comparison,
12070    but it does not yield null for null inputs.  Instead, any null value is
12071    considered unequal to (distinct from) any non-null value, and any two
12072    nulls are considered equal (not distinct).  Thus the result will always
12073    be either true or false, never null.
12074   </para>
12075
12076   <note>
12077    <para>
12078     The SQL specification requires row-wise comparison to return NULL if the
12079     result depends on comparing two NULL values or a NULL and a non-NULL.
12080     <productname>PostgreSQL</productname> does this only when comparing the
12081     results of two row constructors or comparing a row constructor to the
12082     output of a subquery (as in <xref linkend="functions-subquery">).
12083     In other contexts where two composite-type values are compared, two
12084     NULL field values are considered equal, and a NULL is considered larger
12085     than a non-NULL.  This is necessary in order to have consistent sorting
12086     and indexing behavior for composite types.
12087    </para>
12088   </note>
12089
12090   </sect2>
12091  </sect1>
12092
12093  <sect1 id="functions-srf">
12094   <title>Set Returning Functions</title>
12095
12096   <indexterm zone="functions-srf">
12097    <primary>set returning functions</primary>
12098    <secondary>functions</secondary>
12099   </indexterm>
12100
12101   <indexterm>
12102    <primary>generate_series</primary>
12103   </indexterm>
12104
12105   <para>
12106    This section describes functions that possibly return more than one row.
12107    Currently the only functions in this class are series generating functions,
12108    as detailed in <xref linkend="functions-srf-series"> and
12109    <xref linkend="functions-srf-subscripts">.
12110   </para>
12111
12112   <table id="functions-srf-series">
12113    <title>Series Generating Functions</title>
12114    <tgroup cols="4">
12115     <thead>
12116      <row>
12117       <entry>Function</entry>
12118       <entry>Argument Type</entry>
12119       <entry>Return Type</entry>
12120       <entry>Description</entry>
12121      </row>
12122     </thead>
12123
12124     <tbody>
12125      <row>
12126       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>)</function></literal></entry>
12127       <entry><type>int</type> or <type>bigint</type></entry>
12128       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
12129       <entry>
12130        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
12131        with a step size of one
12132       </entry>
12133      </row>
12134
12135      <row>
12136       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</function></literal></entry>
12137       <entry><type>int</type> or <type>bigint</type></entry>
12138       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
12139       <entry>
12140        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
12141        with a step size of <parameter>step</parameter>
12142       </entry>
12143      </row>
12144
12145      <row>
12146       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</function></literal></entry>
12147       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
12148       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
12149       <entry>
12150        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
12151        with a step size of <parameter>step</parameter>
12152       </entry>
12153      </row>
12154
12155     </tbody>
12156    </tgroup>
12157   </table>
12158
12159   <para>
12160    When <parameter>step</parameter> is positive, zero rows are returned if
12161    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
12162    Conversely, when <parameter>step</parameter> is negative, zero rows are
12163    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
12164    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
12165    for <parameter>step</parameter> to be zero. Some examples follow:
12166 <programlisting>
12167 SELECT * FROM generate_series(2,4);
12168  generate_series
12169 -----------------
12170                2
12171                3
12172                4
12173 (3 rows)
12174
12175 SELECT * FROM generate_series(5,1,-2);
12176  generate_series
12177 -----------------
12178                5
12179                3
12180                1
12181 (3 rows)
12182
12183 SELECT * FROM generate_series(4,3);
12184  generate_series
12185 -----------------
12186 (0 rows)
12187
12188 -- this example relies on the date-plus-integer operator
12189 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
12190    dates
12191 ------------
12192  2004-02-05
12193  2004-02-12
12194  2004-02-19
12195 (3 rows)
12196
12197 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
12198                               '2008-03-04 12:00', '10 hours');
12199    generate_series   
12200 ---------------------
12201  2008-03-01 00:00:00
12202  2008-03-01 10:00:00
12203  2008-03-01 20:00:00
12204  2008-03-02 06:00:00
12205  2008-03-02 16:00:00
12206  2008-03-03 02:00:00
12207  2008-03-03 12:00:00
12208  2008-03-03 22:00:00
12209  2008-03-04 08:00:00
12210 (9 rows)
12211 </programlisting>
12212   </para>
12213
12214   <table id="functions-srf-subscripts">
12215    <title>Subscript Generating Functions</title>
12216    <tgroup cols="3">
12217     <thead>
12218      <row>
12219       <entry>Function</entry>
12220       <entry>Return Type</entry>
12221       <entry>Description</entry>
12222      </row>
12223     </thead>
12224
12225     <tbody>
12226      <row>
12227       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</function></literal></entry>
12228       <entry><type>setof int</type></entry>
12229       <entry>
12230        Generate a series comprising the given array's subscripts.
12231       </entry>
12232      </row>
12233
12234      <row>
12235       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</function></literal></entry>
12236       <entry><type>setof int</type></entry>
12237       <entry>
12238        Generate a series comprising the given array's subscripts. When
12239        <parameter>reverse</parameter> is true, the series is returned in
12240        reverse order.
12241       </entry>
12242      </row>
12243
12244     </tbody>
12245    </tgroup>
12246   </table>
12247
12248   <indexterm>
12249    <primary>generate_subscripts</primary>
12250   </indexterm>
12251
12252   <para>
12253    <function>generate_subscripts</> is a convenience function that generates
12254    the set of valid subscripts for the specified dimension of the given
12255    array.
12256    Zero rows are returned for arrays that do not have the requested dimension,
12257    or for NULL arrays (but valid subscripts are returned for NULL array
12258    elements).  Some examples follow:
12259 <programlisting>
12260 -- basic usage
12261 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
12262  s 
12263 ---
12264  1
12265  2
12266  3
12267  4
12268 (4 rows)
12269
12270 -- presenting an array, the subscript and the subscripted
12271 -- value requires a subquery
12272 SELECT * FROM arrays;
12273          a          
12274 --------------------
12275  {-1,-2}
12276  {100,200,300}
12277 (2 rows)
12278
12279 SELECT a AS array, s AS subscript, a[s] AS value
12280 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
12281      array     | subscript | value
12282 ---------------+-----------+-------
12283  {-1,-2}       |         1 |    -1
12284  {-1,-2}       |         2 |    -2
12285  {100,200,300} |         1 |   100
12286  {100,200,300} |         2 |   200
12287  {100,200,300} |         3 |   300
12288 (5 rows)
12289
12290 -- unnest a 2D array
12291 CREATE OR REPLACE FUNCTION unnest2(anyarray)
12292 RETURNS SETOF anyelement AS $$
12293 select $1[i][j]
12294    from generate_subscripts($1,1) g1(i),
12295         generate_subscripts($1,2) g2(j);
12296 $$ LANGUAGE sql IMMUTABLE;
12297 CREATE FUNCTION
12298 postgres=# SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
12299  unnest2 
12300 ---------
12301        1
12302        2
12303        3
12304        4
12305 (4 rows)
12306 </programlisting>
12307   </para>
12308
12309  </sect1>
12310
12311  <sect1 id="functions-info">
12312   <title>System Information Functions</title>
12313
12314   <para>
12315    <xref linkend="functions-info-session-table"> shows several
12316    functions that extract session and system information.
12317   </para>
12318
12319   <para>
12320    In addition to the functions listed in this section, there are a number of
12321    functions related to the statistics system that also provide system
12322    information. See <xref linkend="monitoring-stats-views"> for more
12323    information.
12324   </para>
12325
12326    <table id="functions-info-session-table">
12327     <title>Session Information Functions</title>
12328     <tgroup cols="3">
12329      <thead>
12330       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12331      </thead>
12332
12333      <tbody>
12334       <row>
12335        <entry><literal><function>current_catalog</function></literal></entry>
12336        <entry><type>name</type></entry>
12337        <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
12338       </row>
12339
12340       <row>
12341        <entry><literal><function>current_database()</function></literal></entry>
12342        <entry><type>name</type></entry>
12343        <entry>name of current database</entry>
12344       </row>
12345
12346       <row>
12347        <entry><literal><function>current_query()</function></literal></entry>
12348        <entry><type>text</type></entry>
12349        <entry>text of the currently executing query, as submitted
12350        by the client (might contain more than one statement)</entry>
12351       </row>
12352
12353       <row>
12354        <entry><literal><function>current_schema</function>[()]</literal></entry>
12355        <entry><type>name</type></entry>
12356        <entry>name of current schema</entry>
12357       </row>
12358
12359       <row>
12360        <entry><literal><function>current_schemas(<type>boolean</type>)</function></literal></entry>
12361        <entry><type>name[]</type></entry>
12362        <entry>names of schemas in search path, optionally including implicit schemas</entry>
12363       </row>
12364
12365       <row>
12366        <entry><literal><function>current_user</function></literal></entry>
12367        <entry><type>name</type></entry>
12368        <entry>user name of current execution context</entry>
12369       </row>
12370
12371       <row>
12372        <entry><literal><function>inet_client_addr()</function></literal></entry>
12373        <entry><type>inet</type></entry>
12374        <entry>address of the remote connection</entry>
12375       </row>
12376
12377       <row>
12378        <entry><literal><function>inet_client_port()</function></literal></entry>
12379        <entry><type>int</type></entry>
12380        <entry>port of the remote connection</entry>
12381       </row>
12382
12383       <row>
12384        <entry><literal><function>inet_server_addr()</function></literal></entry>
12385        <entry><type>inet</type></entry>
12386        <entry>address of the local connection</entry>
12387       </row>
12388
12389       <row>
12390        <entry><literal><function>inet_server_port()</function></literal></entry>
12391        <entry><type>int</type></entry>
12392        <entry>port of the local connection</entry>
12393       </row>
12394
12395       <row>
12396        <!-- See also the entry for this in monitoring.sgml -->
12397        <entry><literal><function>pg_backend_pid()</function></literal></entry>
12398        <entry><type>int</type></entry>
12399        <entry>
12400         Process ID of the server process attached to the current session
12401        </entry>
12402       </row>
12403
12404       <row>
12405        <entry><literal><function>pg_conf_load_time()</function></literal></entry>
12406        <entry><type>timestamp with time zone</type></entry>
12407        <entry>configuration load time</entry>
12408       </row>
12409
12410       <row>
12411        <entry><literal><function>pg_is_other_temp_schema(<type>oid</type>)</function></literal></entry>
12412        <entry><type>boolean</type></entry>
12413        <entry>is schema another session's temporary schema?</entry>
12414       </row>
12415
12416       <row>
12417        <entry><literal><function>pg_listening_channels()</function></literal></entry>
12418        <entry><type>setof text</type></entry>
12419        <entry>channel names that the session is currently listening on</entry>
12420       </row>
12421
12422       <row>
12423        <entry><literal><function>pg_my_temp_schema()</function></literal></entry>
12424        <entry><type>oid</type></entry>
12425        <entry>OID of session's temporary schema, or 0 if none</entry>
12426       </row>
12427
12428       <row>
12429        <entry><literal><function>pg_postmaster_start_time()</function></literal></entry>
12430        <entry><type>timestamp with time zone</type></entry>
12431        <entry>server start time</entry>
12432       </row>
12433
12434       <row>
12435        <entry><literal><function>session_user</function></literal></entry>
12436        <entry><type>name</type></entry>
12437        <entry>session user name</entry>
12438       </row>
12439
12440       <row>
12441        <entry><literal><function>user</function></literal></entry>
12442        <entry><type>name</type></entry>
12443        <entry>equivalent to <function>current_user</function></entry>
12444       </row>
12445
12446       <row>
12447        <entry><literal><function>version()</function></literal></entry>
12448        <entry><type>text</type></entry>
12449        <entry><productname>PostgreSQL</> version information</entry>
12450       </row>
12451      </tbody>
12452     </tgroup>
12453    </table>
12454
12455    <note>
12456     <para>
12457      <function>current_catalog</function>, <function>current_schema</function>,
12458      <function>current_user</function>, <function>session_user</function>,
12459      and <function>user</function> have special syntactic status
12460      in <acronym>SQL</acronym>: they must be called without trailing
12461      parentheses.  (In PostgreSQL, parentheses can optionally be used with
12462      <function>current_schema</function>, but not with the others.)
12463     </para>
12464    </note>
12465
12466    <indexterm>
12467     <primary>current_catalog</primary>
12468    </indexterm>
12469
12470    <indexterm>
12471     <primary>current_database</primary>
12472    </indexterm>
12473
12474    <indexterm>
12475     <primary>current_query</primary>
12476    </indexterm>
12477
12478    <indexterm>
12479     <primary>current_schema</primary>
12480    </indexterm>
12481
12482    <indexterm>
12483     <primary>current_schemas</primary>
12484    </indexterm>
12485
12486    <indexterm>
12487     <primary>current_user</primary>
12488    </indexterm>
12489
12490    <indexterm>
12491     <primary>pg_backend_pid</primary>
12492    </indexterm>
12493
12494    <indexterm>
12495     <primary>schema</primary>
12496     <secondary>current</secondary>
12497    </indexterm>
12498
12499    <indexterm>
12500     <primary>search path</primary>
12501     <secondary>current</secondary>
12502    </indexterm>
12503
12504    <indexterm>
12505     <primary>user</primary>
12506     <secondary>current</secondary>
12507    </indexterm>
12508
12509    <indexterm>
12510     <primary>user</primary>
12511    </indexterm>
12512
12513    <para>
12514     The <function>session_user</function> is normally the user who initiated
12515     the current database connection; but superusers can change this setting
12516     with <xref linkend="sql-set-session-authorization">.
12517     The <function>current_user</function> is the user identifier
12518     that is applicable for permission checking. Normally it is equal
12519     to the session user, but it can be changed with
12520     <xref linkend="sql-set-role">.
12521     It also changes during the execution of
12522     functions with the attribute <literal>SECURITY DEFINER</literal>.
12523     In Unix parlance, the session user is the <quote>real user</quote> and
12524     the current user is the <quote>effective user</quote>.
12525    </para>
12526
12527    <para>
12528     <function>current_schema</function> returns the name of the schema that is
12529     first in the search path (or a null value if the search path is
12530     empty).  This is the schema that will be used for any tables or
12531     other named objects that are created without specifying a target schema.
12532     <function>current_schemas(boolean)</function> returns an array of the names of all
12533     schemas presently in the search path.  The Boolean option determines whether or not
12534     implicitly included system schemas such as <literal>pg_catalog</> are included in the
12535     returned search path.
12536    </para>
12537
12538    <note>
12539     <para>
12540      The search path can be altered at run time.  The command is:
12541 <programlisting>
12542 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
12543 </programlisting>
12544     </para>
12545    </note>
12546
12547    <indexterm>
12548     <primary>pg_listening_channels</primary>
12549    </indexterm>
12550
12551    <para>
12552     <function>pg_listening_channels</function> returns a set of names of
12553     channels that the current session is listening to.  See <xref
12554     linkend="sql-listen"> for more information.
12555    </para>
12556
12557    <indexterm>
12558     <primary>inet_client_addr</primary>
12559    </indexterm>
12560
12561    <indexterm>
12562     <primary>inet_client_port</primary>
12563    </indexterm>
12564
12565    <indexterm>
12566     <primary>inet_server_addr</primary>
12567    </indexterm>
12568
12569    <indexterm>
12570     <primary>inet_server_port</primary>
12571    </indexterm>
12572
12573    <para>
12574      <function>inet_client_addr</function> returns the IP address of the
12575      current client, and <function>inet_client_port</function> returns the
12576      port number.
12577      <function>inet_server_addr</function> returns the IP address on which
12578      the server accepted the current connection, and
12579      <function>inet_server_port</function> returns the port number.
12580      All these functions return NULL if the current connection is via a
12581      Unix-domain socket.
12582    </para>
12583
12584    <indexterm>
12585     <primary>pg_my_temp_schema</primary>
12586    </indexterm>
12587
12588    <indexterm>
12589     <primary>pg_is_other_temp_schema</primary>
12590    </indexterm>
12591
12592    <para>
12593     <function>pg_my_temp_schema</function> returns the OID of the current
12594     session's temporary schema, or zero if it has none (because it has not
12595     created any temporary tables).
12596     <function>pg_is_other_temp_schema</function> returns true if the
12597     given OID is the OID of another session's temporary schema.
12598     (This can be useful, for example, to exclude other sessions' temporary
12599     tables from a catalog display.)
12600    </para>
12601
12602    <indexterm>
12603     <primary>pg_postmaster_start_time</primary>
12604    </indexterm>
12605
12606    <para>
12607     <function>pg_postmaster_start_time</function> returns the
12608     <type>timestamp with time zone</type> when the
12609     server started.
12610    </para>
12611
12612    <indexterm>
12613     <primary>pg_conf_load_time</primary>
12614    </indexterm>
12615
12616    <para>
12617     <function>pg_conf_load_time</function> returns the
12618     <type>timestamp with time zone</type> when the
12619     server configuration files were last loaded.
12620     (If the current session was alive at the time, this will be the time
12621     when the session itself re-read the configuration files, so the
12622     reading will vary a little in different sessions.  Otherwise it is
12623     the time when the postmaster process re-read the configuration files.)
12624    </para>
12625
12626    <indexterm>
12627     <primary>version</primary>
12628    </indexterm>
12629
12630    <para>
12631     <function>version</function> returns a string describing the
12632     <productname>PostgreSQL</productname> server's version.
12633    </para>
12634
12635   <indexterm>
12636    <primary>privilege</primary>
12637    <secondary>querying</secondary>
12638   </indexterm>
12639
12640   <para>
12641    <xref linkend="functions-info-access-table"> lists functions that
12642    allow the user to query object access privileges programmatically.
12643    See <xref linkend="ddl-priv"> for more information about
12644    privileges.
12645   </para>
12646
12647    <table id="functions-info-access-table">
12648     <title>Access Privilege Inquiry Functions</title>
12649     <tgroup cols="3">
12650      <thead>
12651       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12652      </thead>
12653
12654      <tbody>
12655       <row>
12656        <entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
12657                                   <parameter>table</parameter>,
12658                                   <parameter>privilege</parameter>)</literal>
12659        </entry>
12660        <entry><type>boolean</type></entry>
12661        <entry>does user have privilege for any column of table</entry>
12662       </row>
12663       <row>
12664        <entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
12665                                   <parameter>privilege</parameter>)</literal>
12666        </entry>
12667        <entry><type>boolean</type></entry>
12668        <entry>does current user have privilege for any column of table</entry>
12669       </row>
12670       <row>
12671        <entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
12672                                   <parameter>table</parameter>,
12673                                   <parameter>column</parameter>,
12674                                   <parameter>privilege</parameter>)</literal>
12675        </entry>
12676        <entry><type>boolean</type></entry>
12677        <entry>does user have privilege for column</entry>
12678       </row>
12679       <row>
12680        <entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
12681                                   <parameter>column</parameter>,
12682                                   <parameter>privilege</parameter>)</literal>
12683        </entry>
12684        <entry><type>boolean</type></entry>
12685        <entry>does current user have privilege for column</entry>
12686       </row>
12687       <row>
12688        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
12689                                   <parameter>database</parameter>,
12690                                   <parameter>privilege</parameter>)</literal>
12691        </entry>
12692        <entry><type>boolean</type></entry>
12693        <entry>does user have privilege for database</entry>
12694       </row>
12695       <row>
12696        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
12697                                   <parameter>privilege</parameter>)</literal>
12698        </entry>
12699        <entry><type>boolean</type></entry>
12700        <entry>does current user have privilege for database</entry>
12701       </row>
12702       <row>
12703        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
12704                                   <parameter>fdw</parameter>,
12705                                   <parameter>privilege</parameter>)</literal>
12706        </entry>
12707        <entry><type>boolean</type></entry>
12708        <entry>does user have privilege for foreign-data wrapper</entry>
12709       </row>
12710       <row>
12711        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
12712                                   <parameter>privilege</parameter>)</literal>
12713        </entry>
12714        <entry><type>boolean</type></entry>
12715        <entry>does current user have privilege for foreign-data wrapper</entry>
12716       </row>
12717       <row>
12718        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
12719                                   <parameter>function</parameter>,
12720                                   <parameter>privilege</parameter>)</literal>
12721        </entry>
12722        <entry><type>boolean</type></entry>
12723        <entry>does user have privilege for function</entry>
12724       </row>
12725       <row>
12726        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
12727                                   <parameter>privilege</parameter>)</literal>
12728        </entry>
12729        <entry><type>boolean</type></entry>
12730        <entry>does current user have privilege for function</entry>
12731       </row>
12732       <row>
12733        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
12734                                   <parameter>language</parameter>,
12735                                   <parameter>privilege</parameter>)</literal>
12736        </entry>
12737        <entry><type>boolean</type></entry>
12738        <entry>does user have privilege for language</entry>
12739       </row>
12740       <row>
12741        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
12742                                   <parameter>privilege</parameter>)</literal>
12743        </entry>
12744        <entry><type>boolean</type></entry>
12745        <entry>does current user have privilege for language</entry>
12746       </row>
12747       <row>
12748        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
12749                                   <parameter>schema</parameter>,
12750                                   <parameter>privilege</parameter>)</literal>
12751        </entry>
12752        <entry><type>boolean</type></entry>
12753        <entry>does user have privilege for schema</entry>
12754       </row>
12755       <row>
12756        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
12757                                   <parameter>privilege</parameter>)</literal>
12758        </entry>
12759        <entry><type>boolean</type></entry>
12760        <entry>does current user have privilege for schema</entry>
12761       </row>
12762       <row>
12763        <entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
12764                                   <parameter>server</parameter>,
12765                                   <parameter>privilege</parameter>)</literal>
12766        </entry>
12767        <entry><type>boolean</type></entry>
12768        <entry>does user have privilege for foreign server</entry>
12769       </row>
12770       <row>
12771        <entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
12772                                   <parameter>privilege</parameter>)</literal>
12773        </entry>
12774        <entry><type>boolean</type></entry>
12775        <entry>does current user have privilege for foreign server</entry>
12776       </row>
12777       <row>
12778        <entry><literal><function>has_sequence_privilege</function>(<parameter>user</parameter>,
12779                                   <parameter>sequence</parameter>,
12780                                   <parameter>privilege</parameter>)</literal>
12781        </entry>
12782        <entry><type>boolean</type></entry>
12783        <entry>does user have privilege for sequence</entry>
12784       </row>
12785       <row>
12786        <entry><literal><function>has_sequence_privilege</function>(<parameter>sequence</parameter>,
12787                                   <parameter>privilege</parameter>)</literal>
12788        </entry>
12789        <entry><type>boolean</type></entry>
12790        <entry>does current user have privilege for sequence</entry>
12791       </row>
12792       <row>
12793        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
12794                                   <parameter>table</parameter>,
12795                                   <parameter>privilege</parameter>)</literal>
12796        </entry>
12797        <entry><type>boolean</type></entry>
12798        <entry>does user have privilege for table</entry>
12799       </row>
12800       <row>
12801        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
12802                                   <parameter>privilege</parameter>)</literal>
12803        </entry>
12804        <entry><type>boolean</type></entry>
12805        <entry>does current user have privilege for table</entry>
12806       </row>
12807       <row>
12808        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
12809                                   <parameter>tablespace</parameter>,
12810                                   <parameter>privilege</parameter>)</literal>
12811        </entry>
12812        <entry><type>boolean</type></entry>
12813        <entry>does user have privilege for tablespace</entry>
12814       </row>
12815       <row>
12816        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
12817                                   <parameter>privilege</parameter>)</literal>
12818        </entry>
12819        <entry><type>boolean</type></entry>
12820        <entry>does current user have privilege for tablespace</entry>
12821       </row>
12822       <row>
12823        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
12824                                   <parameter>role</parameter>,
12825                                   <parameter>privilege</parameter>)</literal>
12826        </entry>
12827        <entry><type>boolean</type></entry>
12828        <entry>does user have privilege for role</entry>
12829       </row>
12830       <row>
12831        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
12832                                   <parameter>privilege</parameter>)</literal>
12833        </entry>
12834        <entry><type>boolean</type></entry>
12835        <entry>does current user have privilege for role</entry>
12836       </row>
12837      </tbody>
12838     </tgroup>
12839    </table>
12840
12841    <indexterm>
12842     <primary>has_any_column_privilege</primary>
12843    </indexterm>
12844    <indexterm>
12845     <primary>has_column_privilege</primary>
12846    </indexterm>
12847    <indexterm>
12848     <primary>has_database_privilege</primary>
12849    </indexterm>
12850    <indexterm>
12851     <primary>has_function_privilege</primary>
12852    </indexterm>
12853    <indexterm>
12854     <primary>has_foreign_data_wrapper_privilege</primary>
12855    </indexterm>
12856    <indexterm>
12857     <primary>has_language_privilege</primary>
12858    </indexterm>
12859    <indexterm>
12860     <primary>has_schema_privilege</primary>
12861    </indexterm>
12862    <indexterm>
12863     <primary>has_server_privilege</primary>
12864    </indexterm>
12865    <indexterm>
12866     <primary>has_sequence_privilege</primary>
12867    </indexterm>
12868    <indexterm>
12869     <primary>has_table_privilege</primary>
12870    </indexterm>
12871    <indexterm>
12872     <primary>has_tablespace_privilege</primary>
12873    </indexterm>
12874    <indexterm>
12875     <primary>pg_has_role</primary>
12876    </indexterm>
12877
12878    <para>
12879     <function>has_table_privilege</function> checks whether a user
12880     can access a table in a particular way.  The user can be
12881     specified by name, by OID (<literal>pg_authid.oid</literal>),
12882     <literal>public</> to indicate the PUBLIC pseudo-role, or if the argument is
12883     omitted
12884     <function>current_user</function> is assumed.  The table can be specified
12885     by name or by OID.  (Thus, there are actually six variants of
12886     <function>has_table_privilege</function>, which can be distinguished by
12887     the number and types of their arguments.)  When specifying by name,
12888     the name can be schema-qualified if necessary.
12889     The desired access privilege type
12890     is specified by a text string, which must evaluate to one of the
12891     values <literal>SELECT</literal>, <literal>INSERT</literal>,
12892     <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
12893     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.  Optionally,
12894     <literal>WITH GRANT OPTION</> can be added to a privilege type to test
12895     whether the privilege is held with grant option.  Also, multiple privilege
12896     types can be listed separated by commas, in which case the result will
12897     be <literal>true</> if any of the listed privileges is held.
12898     (Case of the privilege string is not significant, and extra whitespace
12899     is allowed between but not within privilege names.)
12900     Some examples:
12901 <programlisting>
12902 SELECT has_table_privilege('myschema.mytable', 'select');
12903 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
12904 </programlisting>
12905    </para>
12906
12907    <para>
12908     <function>has_sequence_privilege</function> checks whether a user
12909     can access a sequence in a particular way.  The possibilities for its
12910     arguments are analogous to <function>has_table_privilege</function>.
12911     The desired access privilege type must evaluate to one of
12912     <literal>USAGE</literal>,
12913     <literal>SELECT</literal>, or
12914     <literal>UPDATE</literal>.
12915    </para>
12916
12917    <para>
12918     <function>has_any_column_privilege</function> checks whether a user can
12919     access any column of a table in a particular way.
12920     Its argument possibilities
12921     are analogous to <function>has_table_privilege</>,
12922     except that the desired access privilege type must evaluate to some
12923     combination of
12924     <literal>SELECT</literal>,
12925     <literal>INSERT</literal>,
12926     <literal>UPDATE</literal>, or
12927     <literal>REFERENCES</literal>.  Note that having any of these privileges
12928     at the table level implicitly grants it for each column of the table,
12929     so <function>has_any_column_privilege</function> will always return
12930     <literal>true</> if <function>has_table_privilege</> does for the same
12931     arguments.  But <function>has_any_column_privilege</> also succeeds if
12932     there is a column-level grant of the privilege for at least one column.
12933    </para>
12934
12935    <para>
12936     <function>has_column_privilege</function> checks whether a user
12937     can access a column in a particular way.
12938     Its argument possibilities
12939     are analogous to <function>has_table_privilege</function>,
12940     with the addition that the column can be specified either by name
12941     or attribute number.
12942     The desired access privilege type must evaluate to some combination of
12943     <literal>SELECT</literal>,
12944     <literal>INSERT</literal>,
12945     <literal>UPDATE</literal>, or
12946     <literal>REFERENCES</literal>.  Note that having any of these privileges
12947     at the table level implicitly grants it for each column of the table.
12948    </para>
12949
12950    <para>
12951     <function>has_database_privilege</function> checks whether a user
12952     can access a database in a particular way.
12953     Its argument possibilities
12954     are analogous to <function>has_table_privilege</function>.
12955     The desired access privilege type must evaluate to some combination of
12956     <literal>CREATE</literal>,
12957     <literal>CONNECT</literal>,
12958     <literal>TEMPORARY</literal>, or
12959     <literal>TEMP</literal> (which is equivalent to
12960     <literal>TEMPORARY</literal>).
12961    </para>
12962
12963    <para>
12964     <function>has_function_privilege</function> checks whether a user
12965     can access a function in a particular way.
12966     Its argument possibilities
12967     are analogous to <function>has_table_privilege</function>.
12968     When specifying a function by a text string rather than by OID,
12969     the allowed input is the same as for the <type>regprocedure</> data type
12970     (see <xref linkend="datatype-oid">).
12971     The desired access privilege type must evaluate to
12972     <literal>EXECUTE</literal>.
12973     An example is:
12974 <programlisting>
12975 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
12976 </programlisting>
12977    </para>
12978
12979    <para>
12980     <function>has_foreign_data_wrapper_privilege</function> checks whether a user
12981     can access a foreign-data wrapper in a particular way.
12982     Its argument possibilities
12983     are analogous to <function>has_table_privilege</function>.
12984     The desired access privilege type must evaluate to
12985     <literal>USAGE</literal>.
12986    </para>
12987
12988    <para>
12989     <function>has_language_privilege</function> checks whether a user
12990     can access a procedural language in a particular way.
12991     Its argument possibilities
12992     are analogous to <function>has_table_privilege</function>.
12993     The desired access privilege type must evaluate to
12994     <literal>USAGE</literal>.
12995    </para>
12996
12997    <para>
12998     <function>has_schema_privilege</function> checks whether a user
12999     can access a schema in a particular way.
13000     Its argument possibilities
13001     are analogous to <function>has_table_privilege</function>.
13002     The desired access privilege type must evaluate to some combination of
13003     <literal>CREATE</literal> or
13004     <literal>USAGE</literal>.
13005    </para>
13006
13007    <para>
13008     <function>has_server_privilege</function> checks whether a user
13009     can access a foreign server in a particular way.
13010     Its argument possibilities
13011     are analogous to <function>has_table_privilege</function>.
13012     The desired access privilege type must evaluate to
13013     <literal>USAGE</literal>.
13014    </para>
13015
13016    <para>
13017     <function>has_tablespace_privilege</function> checks whether a user
13018     can access a tablespace in a particular way.
13019     Its argument possibilities
13020     are analogous to <function>has_table_privilege</function>.
13021     The desired access privilege type must evaluate to
13022     <literal>CREATE</literal>.
13023    </para>
13024
13025    <para>
13026     <function>pg_has_role</function> checks whether a user
13027     can access a role in a particular way.
13028     Its argument possibilities
13029     are analogous to <function>has_table_privilege</function>,
13030     except that <literal>public</> is not allowed as a user name.
13031     The desired access privilege type must evaluate to some combination of
13032     <literal>MEMBER</literal> or
13033     <literal>USAGE</literal>.
13034     <literal>MEMBER</literal> denotes direct or indirect membership in
13035     the role (that is, the right to do <command>SET ROLE</>), while
13036     <literal>USAGE</literal> denotes whether the privileges of the role
13037     are immediately available without doing <command>SET ROLE</>.
13038    </para>
13039
13040   <para>
13041    <xref linkend="functions-info-schema-table"> shows functions that
13042    determine whether a certain object is <firstterm>visible</> in the
13043    current schema search path.
13044    For example, a table is said to be visible if its
13045    containing schema is in the search path and no table of the same
13046    name appears earlier in the search path.  This is equivalent to the
13047    statement that the table can be referenced by name without explicit
13048    schema qualification.  To list the names of all visible tables:
13049 <programlisting>
13050 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
13051 </programlisting>
13052   </para>
13053
13054    <table id="functions-info-schema-table">
13055     <title>Schema Visibility Inquiry Functions</title>
13056     <tgroup cols="3">
13057      <thead>
13058       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13059      </thead>
13060
13061      <tbody>
13062       <row>
13063        <entry><literal><function>pg_collation_is_visible(<parameter>collation_oid</parameter>)</function></literal>
13064        </entry>
13065        <entry><type>boolean</type></entry>
13066        <entry>is collation visible in search path</entry>
13067       </row>
13068       <row>
13069        <entry><literal><function>pg_conversion_is_visible(<parameter>conversion_oid</parameter>)</function></literal>
13070        </entry>
13071        <entry><type>boolean</type></entry>
13072        <entry>is conversion visible in search path</entry>
13073       </row>
13074       <row>
13075        <entry><literal><function>pg_function_is_visible(<parameter>function_oid</parameter>)</function></literal>
13076        </entry>
13077        <entry><type>boolean</type></entry>
13078        <entry>is function visible in search path</entry>
13079       </row>
13080       <row>
13081        <entry><literal><function>pg_opclass_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
13082        </entry>
13083        <entry><type>boolean</type></entry>
13084        <entry>is operator class visible in search path</entry>
13085       </row>
13086       <row>
13087        <entry><literal><function>pg_operator_is_visible(<parameter>operator_oid</parameter>)</function></literal>
13088        </entry>
13089        <entry><type>boolean</type></entry>
13090        <entry>is operator visible in search path</entry>
13091       </row>
13092       <row>
13093        <entry><literal><function>pg_table_is_visible(<parameter>table_oid</parameter>)</function></literal>
13094        </entry>
13095        <entry><type>boolean</type></entry>
13096        <entry>is table visible in search path</entry>
13097       </row>
13098       <row>
13099        <entry><literal><function>pg_ts_config_is_visible(<parameter>config_oid</parameter>)</function></literal>
13100        </entry>
13101        <entry><type>boolean</type></entry>
13102        <entry>is text search configuration visible in search path</entry>
13103       </row>
13104       <row>
13105        <entry><literal><function>pg_ts_dict_is_visible(<parameter>dict_oid</parameter>)</function></literal>
13106        </entry>
13107        <entry><type>boolean</type></entry>
13108        <entry>is text search dictionary visible in search path</entry>
13109       </row>
13110       <row>
13111        <entry><literal><function>pg_ts_parser_is_visible(<parameter>parser_oid</parameter>)</function></literal>
13112        </entry>
13113        <entry><type>boolean</type></entry>
13114        <entry>is text search parser visible in search path</entry>
13115       </row>
13116       <row>
13117        <entry><literal><function>pg_ts_template_is_visible(<parameter>template_oid</parameter>)</function></literal>
13118        </entry>
13119        <entry><type>boolean</type></entry>
13120        <entry>is text search template visible in search path</entry>
13121       </row>
13122       <row>
13123        <entry><literal><function>pg_type_is_visible(<parameter>type_oid</parameter>)</function></literal>
13124        </entry>
13125        <entry><type>boolean</type></entry>
13126        <entry>is type (or domain) visible in search path</entry>
13127       </row>
13128      </tbody>
13129     </tgroup>
13130    </table>
13131
13132    <indexterm>
13133     <primary>pg_collation_is_visible</primary>
13134    </indexterm>
13135    <indexterm>
13136     <primary>pg_conversion_is_visible</primary>
13137    </indexterm>
13138    <indexterm>
13139     <primary>pg_function_is_visible</primary>
13140    </indexterm>
13141    <indexterm>
13142     <primary>pg_opclass_is_visible</primary>
13143    </indexterm>
13144    <indexterm>
13145     <primary>pg_operator_is_visible</primary>
13146    </indexterm>
13147    <indexterm>
13148     <primary>pg_table_is_visible</primary>
13149    </indexterm>
13150    <indexterm>
13151     <primary>pg_ts_config_is_visible</primary>
13152    </indexterm>
13153    <indexterm>
13154     <primary>pg_ts_dict_is_visible</primary>
13155    </indexterm>
13156    <indexterm>
13157     <primary>pg_ts_parser_is_visible</primary>
13158    </indexterm>
13159    <indexterm>
13160     <primary>pg_ts_template_is_visible</primary>
13161    </indexterm>
13162    <indexterm>
13163     <primary>pg_type_is_visible</primary>
13164    </indexterm>
13165
13166    <para>
13167     Each function performs the visibility check for one type of database
13168     object.  Note that <function>pg_table_is_visible</function> can also be used
13169     with views, indexes and sequences; <function>pg_type_is_visible</function>
13170     can also be used with domains. For functions and operators, an object in
13171     the search path is visible if there is no object of the same name
13172     <emphasis>and argument data type(s)</> earlier in the path.  For operator
13173     classes, both name and associated index access method are considered.
13174    </para>
13175
13176    <para>
13177     All these functions require object OIDs to identify the object to be
13178     checked.  If you want to test an object by name, it is convenient to use
13179     the OID alias types (<type>regclass</>, <type>regtype</>,
13180     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
13181     or <type>regdictionary</>),
13182     for example:
13183 <programlisting>
13184 SELECT pg_type_is_visible('myschema.widget'::regtype);
13185 </programlisting>
13186     Note that it would not make much sense to test a non-schema-qualified
13187     type name in this way &mdash; if the name can be recognized at all, it must be visible.
13188    </para>
13189
13190    <indexterm>
13191     <primary>format_type</primary>
13192    </indexterm>
13193
13194    <indexterm>
13195     <primary>pg_get_constraintdef</primary>
13196    </indexterm>
13197
13198    <indexterm>
13199     <primary>pg_get_expr</primary>
13200    </indexterm>
13201
13202    <indexterm>
13203     <primary>pg_get_functiondef</primary>
13204    </indexterm>
13205
13206    <indexterm>
13207     <primary>pg_get_function_arguments</primary>
13208    </indexterm>
13209
13210    <indexterm>
13211     <primary>pg_get_function_identity_arguments</primary>
13212    </indexterm>
13213
13214    <indexterm>
13215     <primary>pg_get_function_result</primary>
13216    </indexterm>
13217
13218    <indexterm>
13219     <primary>pg_get_indexdef</primary>
13220    </indexterm>
13221
13222    <indexterm>
13223     <primary>pg_get_keywords</primary>
13224    </indexterm>
13225
13226    <indexterm>
13227     <primary>pg_get_ruledef</primary>
13228    </indexterm>
13229
13230    <indexterm>
13231     <primary>pg_get_serial_sequence</primary>
13232    </indexterm>
13233
13234    <indexterm>
13235     <primary>pg_get_triggerdef</primary>
13236    </indexterm>
13237
13238    <indexterm>
13239     <primary>pg_get_userbyid</primary>
13240    </indexterm>
13241
13242    <indexterm>
13243     <primary>pg_get_viewdef</primary>
13244    </indexterm>
13245
13246    <indexterm>
13247     <primary>pg_options_to_table</primary>
13248    </indexterm>
13249
13250    <indexterm>
13251     <primary>pg_tablespace_databases</primary>
13252    </indexterm>
13253
13254    <indexterm>
13255     <primary>pg_typeof</primary>
13256    </indexterm>
13257
13258   <para>
13259    <xref linkend="functions-info-catalog-table"> lists functions that
13260    extract information from the system catalogs.
13261   </para>
13262
13263    <table id="functions-info-catalog-table">
13264     <title>System Catalog Information Functions</title>
13265     <tgroup cols="3">
13266      <thead>
13267       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13268      </thead>
13269
13270      <tbody>
13271       <row>
13272        <entry><literal><function>format_type(<parameter>type_oid</parameter>, <parameter>typemod</>)</function></literal></entry>
13273        <entry><type>text</type></entry>
13274        <entry>get SQL name of a data type</entry>
13275       </row>
13276       <row>
13277        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>)</function></literal></entry>
13278        <entry><type>text</type></entry>
13279        <entry>get definition of a constraint</entry>
13280       </row>
13281       <row>
13282        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13283        <entry><type>text</type></entry>
13284        <entry>get definition of a constraint</entry>
13285       </row>
13286       <row>
13287        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>)</function></literal></entry>
13288        <entry><type>text</type></entry>
13289        <entry>decompile internal form of an expression, assuming that any Vars
13290        in it refer to the relation indicated by the second parameter</entry>
13291       </row>
13292       <row>
13293        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</function></literal></entry>
13294        <entry><type>text</type></entry>
13295        <entry>decompile internal form of an expression, assuming that any Vars
13296        in it refer to the relation indicated by the second parameter</entry>
13297       </row>
13298       <row>
13299        <entry><literal><function>pg_get_functiondef(<parameter>func_oid</parameter>)</function></literal></entry>
13300        <entry><type>text</type></entry>
13301        <entry>get definition of a function</entry>
13302       </row>
13303       <row>
13304        <entry><literal><function>pg_get_function_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
13305        <entry><type>text</type></entry>
13306        <entry>get argument list of function's definition (with default values)</entry>
13307       </row>
13308       <row>
13309        <entry><literal><function>pg_get_function_identity_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
13310        <entry><type>text</type></entry>
13311        <entry>get argument list to identify a function (without default values)</entry>
13312       </row>
13313       <row>
13314        <entry><literal><function>pg_get_function_result(<parameter>func_oid</parameter>)</function></literal></entry>
13315        <entry><type>text</type></entry>
13316        <entry>get <literal>RETURNS</> clause for function</entry>
13317       </row>
13318       <row>
13319        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>)</function></literal></entry>
13320        <entry><type>text</type></entry>
13321        <entry>get <command>CREATE INDEX</> command for index</entry>
13322       </row>
13323       <row>
13324        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</function></literal></entry>
13325        <entry><type>text</type></entry>
13326        <entry>get <command>CREATE INDEX</> command for index,
13327        or definition of just one index column when
13328        <parameter>column_no</> is not zero</entry>
13329       </row>
13330       <row>
13331        <entry><literal><function>pg_get_keywords()</function></literal></entry>
13332        <entry><type>setof record</type></entry>
13333        <entry>get list of SQL keywords and their categories</entry>
13334       </row>
13335       <row>
13336        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>)</function></literal></entry>
13337        <entry><type>text</type></entry>
13338        <entry>get <command>CREATE RULE</> command for rule</entry>
13339       </row>
13340       <row>
13341        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13342        <entry><type>text</type></entry>
13343        <entry>get <command>CREATE RULE</> command for rule</entry>
13344       </row>
13345       <row>
13346        <entry><literal><function>pg_get_serial_sequence(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</function></literal></entry>
13347        <entry><type>text</type></entry>
13348        <entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
13349        uses</entry>
13350       </row>
13351       <row>
13352        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
13353        <entry><type>text</type></entry>
13354        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
13355       </row>
13356       <row>
13357        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>, <parameter>pretty_bool</>)</entry>
13358        <entry><type>text</type></entry>
13359        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
13360       </row>
13361       <row>
13362        <entry><literal><function>pg_get_userbyid(<parameter>role_oid</parameter>)</function></literal></entry>
13363        <entry><type>name</type></entry>
13364        <entry>get role name with given OID</entry>
13365       </row>
13366       <row>
13367        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>)</function></literal></entry>
13368        <entry><type>text</type></entry>
13369        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
13370       </row>
13371       <row>
13372        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13373        <entry><type>text</type></entry>
13374        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
13375       </row>
13376       <row>
13377        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>)</function></literal></entry>
13378        <entry><type>text</type></entry>
13379        <entry>get underlying <command>SELECT</command> command for view</entry>
13380       </row>
13381       <row>
13382        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
13383        <entry><type>text</type></entry>
13384        <entry>get underlying <command>SELECT</command> command for view</entry>
13385       </row>
13386       <row>
13387        <entry><literal><function>pg_options_to_table(<parameter>reloptions</parameter>)</function></literal></entry>
13388        <entry><type>setof record</type></entry>
13389        <entry>get the set of storage option name/value pairs</entry>
13390       </row>
13391       <row>
13392        <entry><literal><function>pg_tablespace_databases(<parameter>tablespace_oid</parameter>)</function></literal></entry>
13393        <entry><type>setof oid</type></entry>
13394        <entry>get the set of database OIDs that have objects in the tablespace</entry>
13395       </row>
13396       <row>
13397        <entry><literal><function>pg_describe_object(<parameter>catalog_id</parameter>, <parameter>object_id</parameter>, <parameter>object_sub_id</parameter>)</function>)</literal></entry>
13398        <entry><type>text</type></entry>
13399        <entry>get description of a database object</entry>
13400       </row>
13401       <row>
13402        <entry><literal><function>pg_typeof(<parameter>any</parameter>)</function></literal></entry>
13403        <entry><type>regtype</type></entry>
13404        <entry>get the data type of any value</entry>
13405       </row>
13406      </tbody>
13407     </tgroup>
13408    </table>
13409
13410   <para>
13411    <function>format_type</function> returns the SQL name of a data type that
13412    is identified by its type OID and possibly a type modifier.  Pass NULL
13413    for the type modifier if no specific modifier is known.
13414   </para>
13415
13416   <para>
13417    <function>pg_get_keywords</function> returns a set of records describing
13418    the SQL keywords recognized by the server. The <structfield>word</> column
13419    contains the keyword.  The <structfield>catcode</> column contains a
13420    category code: <literal>U</> for unreserved, <literal>C</> for column name,
13421    <literal>T</> for type or function name, or <literal>R</> for reserved.
13422    The <structfield>catdesc</> column contains a possibly-localized string
13423    describing the category.
13424   </para>
13425
13426   <para>
13427    <function>pg_get_constraintdef</function>,
13428    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
13429    and <function>pg_get_triggerdef</function>, respectively reconstruct the
13430    creating command for a constraint, index, rule, or trigger. (Note that this
13431    is a decompiled reconstruction, not the original text of the command.)
13432    <function>pg_get_expr</function> decompiles the internal form of an
13433    individual expression, such as the default value for a column.  It can be
13434    useful when examining the contents of system catalogs.  If the expression
13435    might contain Vars, specify the OID of the relation they refer to as the
13436    second parameter; if no Vars are expected, zero is sufficient.
13437    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
13438    query that defines a view. Most of these functions come in two variants,
13439    one of which can optionally <quote>pretty-print</> the result.  The
13440    pretty-printed format is more readable, but the default format is more
13441    likely to be interpreted the same way by future versions of
13442    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
13443    purposes.  Passing <literal>false</> for the pretty-print parameter yields
13444    the same result as the variant that does not have the parameter at all.
13445   </para>
13446
13447   <para>
13448    <function>pg_get_functiondef</> returns a complete
13449    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
13450    <function>pg_get_function_arguments</function> returns the argument list
13451    of a function, in the form it would need to appear in within
13452    <command>CREATE FUNCTION</>.
13453    <function>pg_get_function_result</function> similarly returns the
13454    appropriate <literal>RETURNS</> clause for the function.
13455    <function>pg_get_function_identity_arguments</function> returns the
13456    argument list necessary to identify a function, in the form it
13457    would need to appear in within <command>ALTER FUNCTION</>, for
13458    instance.  This form omits default values.
13459   </para>
13460
13461   <para>
13462    <function>pg_get_serial_sequence</function> returns the name of the
13463    sequence associated with a column, or NULL if no sequence is associated
13464    with the column.  The first input parameter is a table name with
13465    optional schema, and the second parameter is a column name.  Because
13466    the first parameter is potentially a schema and table, it is not treated
13467    as a double-quoted identifier, meaning it is lower cased by default,
13468    while the second parameter, being just a column name, is treated as
13469    double-quoted and has its case preserved.  The function returns a value
13470    suitably formatted for passing to sequence functions (see <xref
13471    linkend="functions-sequence">).  This association can be modified or
13472    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
13473    probably should have been called
13474    <function>pg_get_owned_sequence</function>; its current name reflects the fact
13475    that it's typically used with <type>serial</> or <type>bigserial</>
13476    columns.)
13477   </para>
13478
13479   <para>
13480    <function>pg_get_userbyid</function> extracts a role's name given
13481    its OID.
13482   </para>
13483
13484   <para>
13485    <function>pg_options_to_table</function> returns the set of storage
13486    option name/value pairs
13487    (<literal>option_name</>/<literal>option_value</>) when passed
13488    <structname>pg_class</>.<structfield>reloptions</> or
13489    <structname>pg_attribute</>.<structfield>attoptions</>.
13490   </para>
13491
13492   <para>
13493    <function>pg_tablespace_databases</function> allows a tablespace to be
13494    examined. It returns the set of OIDs of databases that have objects stored
13495    in the tablespace. If this function returns any rows, the tablespace is not
13496    empty and cannot be dropped. To display the specific objects populating the
13497    tablespace, you will need to connect to the databases identified by
13498    <function>pg_tablespace_databases</function> and query their
13499    <structname>pg_class</> catalogs.
13500   </para>
13501
13502   <para>
13503    <function>pg_describe_object</function> returns a description of a database
13504    object specified by catalog OID, object OID and a (possibly zero) sub-object ID.
13505    This is useful to determine the identity of an object as stored in the
13506    <structname>pg_depend</structname> catalog.
13507   </para>
13508
13509   <para>
13510    <function>pg_typeof</function> returns the OID of the data type of the
13511    value that is passed to it.  This can be helpful for troubleshooting or
13512    dynamically constructing SQL queries.  The function is declared as
13513    returning <type>regtype</>, which is an OID alias type (see
13514    <xref linkend="datatype-oid">); this means that it is the same as an
13515    OID for comparison purposes but displays as a type name.  For example:
13516 <programlisting>
13517 SELECT pg_typeof(33);
13518
13519  pg_typeof 
13520 -----------
13521  integer
13522 (1 row)
13523
13524 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
13525  typlen 
13526 --------
13527       4
13528 (1 row)
13529 </programlisting>
13530   </para>
13531
13532    <indexterm>
13533     <primary>col_description</primary>
13534    </indexterm>
13535
13536    <indexterm>
13537     <primary>obj_description</primary>
13538    </indexterm>
13539
13540    <indexterm>
13541     <primary>shobj_description</primary>
13542    </indexterm>
13543
13544    <indexterm>
13545     <primary>comment</primary>
13546     <secondary sortas="database objects">about database objects</secondary>
13547    </indexterm>
13548
13549    <para>
13550     The functions shown in <xref linkend="functions-info-comment-table">
13551     extract comments previously stored with the <xref linkend="sql-comment">
13552     command.  A null value is returned if no
13553     comment could be found for the specified parameters.
13554    </para>
13555
13556    <table id="functions-info-comment-table">
13557     <title>Comment Information Functions</title>
13558     <tgroup cols="3">
13559      <thead>
13560       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13561      </thead>
13562
13563      <tbody>
13564       <row>
13565        <entry><literal><function>col_description(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</function></literal></entry>
13566        <entry><type>text</type></entry>
13567        <entry>get comment for a table column</entry>
13568       </row>
13569       <row>
13570        <entry><literal><function>obj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
13571        <entry><type>text</type></entry>
13572        <entry>get comment for a database object</entry>
13573       </row>
13574       <row>
13575        <entry><literal><function>obj_description(<parameter>object_oid</parameter>)</function></literal></entry>
13576        <entry><type>text</type></entry>
13577        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
13578       </row>
13579       <row>
13580        <entry><literal><function>shobj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
13581        <entry><type>text</type></entry>
13582        <entry>get comment for a shared database object</entry>
13583       </row>
13584      </tbody>
13585     </tgroup>
13586    </table>
13587
13588    <para>
13589     <function>col_description</function> returns the comment for a table
13590     column, which is specified by the OID of its table and its column number.
13591     (<function>obj_description</function> cannot be used for table columns
13592     since columns do not have OIDs of their own.)
13593    </para>
13594
13595    <para>
13596     The two-parameter form of <function>obj_description</function> returns the
13597     comment for a database object specified by its OID and the name of the
13598     containing system catalog.  For example,
13599     <literal>obj_description(123456,'pg_class')</literal>
13600     would retrieve the comment for the table with OID 123456.
13601     The one-parameter form of <function>obj_description</function> requires only
13602     the object OID.  It is deprecated since there is no guarantee that
13603     OIDs are unique across different system catalogs; therefore, the wrong
13604     comment might be returned.
13605    </para>
13606
13607    <para>
13608     <function>shobj_description</function> is used just like
13609     <function>obj_description</function> except it is used for retrieving
13610     comments on shared objects.  Some system catalogs are global to all
13611     databases within each cluster, and the descriptions for objects in them
13612     are stored globally as well.
13613    </para>
13614
13615    <indexterm>
13616     <primary>txid_current</primary>
13617    </indexterm>
13618
13619    <indexterm>
13620     <primary>txid_current_snapshot</primary>
13621    </indexterm>
13622
13623    <indexterm>
13624     <primary>txid_snapshot_xip</primary>
13625    </indexterm>
13626
13627    <indexterm>
13628     <primary>txid_snapshot_xmax</primary>
13629    </indexterm>
13630
13631    <indexterm>
13632     <primary>txid_snapshot_xmin</primary>
13633    </indexterm>
13634
13635    <indexterm>
13636     <primary>txid_visible_in_snapshot</primary>
13637    </indexterm>
13638
13639    <para>
13640     The functions shown in <xref linkend="functions-txid-snapshot">
13641     provide server transaction information in an exportable form.  The main
13642     use of these functions is to determine which transactions were committed
13643     between two snapshots.
13644    </para>
13645
13646    <table id="functions-txid-snapshot">
13647     <title>Transaction IDs and Snapshots</title>
13648     <tgroup cols="3">
13649      <thead>
13650       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13651      </thead>
13652
13653      <tbody>
13654       <row>
13655        <entry><literal><function>txid_current()</function></literal></entry>
13656        <entry><type>bigint</type></entry>
13657        <entry>get current transaction ID</entry>
13658       </row>
13659       <row>
13660        <entry><literal><function>txid_current_snapshot()</function></literal></entry>
13661        <entry><type>txid_snapshot</type></entry>
13662        <entry>get current snapshot</entry>
13663       </row>
13664       <row>
13665        <entry><literal><function>txid_snapshot_xip(<parameter>txid_snapshot</parameter>)</function></literal></entry>
13666        <entry><type>setof bigint</type></entry>
13667        <entry>get in-progress transaction IDs in snapshot</entry>
13668       </row>
13669       <row>
13670        <entry><literal><function>txid_snapshot_xmax(<parameter>txid_snapshot</parameter>)</function></literal></entry>
13671        <entry><type>bigint</type></entry>
13672        <entry>get xmax of snapshot</entry>
13673       </row>
13674       <row>
13675        <entry><literal><function>txid_snapshot_xmin(<parameter>txid_snapshot</parameter>)</function></literal></entry>
13676        <entry><type>bigint</type></entry>
13677        <entry>get xmin of snapshot</entry>
13678       </row>
13679       <row>
13680        <entry><literal><function>txid_visible_in_snapshot(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</function></literal></entry>
13681        <entry><type>boolean</type></entry>
13682        <entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
13683       </row>
13684      </tbody>
13685     </tgroup>
13686    </table>
13687
13688    <para>
13689     The internal transaction ID type (<type>xid</>) is 32 bits wide and
13690     wraps around every 4 billion transactions.  However, these functions
13691     export a 64-bit format that is extended with an <quote>epoch</> counter
13692     so it will not wrap around during the life of an installation.
13693     The data type used by these functions, <type>txid_snapshot</type>,
13694     stores information about transaction ID
13695     visibility at a particular moment in time.  Its components are
13696     described in <xref linkend="functions-txid-snapshot-parts">.
13697    </para>
13698
13699    <table id="functions-txid-snapshot-parts">
13700     <title>Snapshot Components</title>
13701     <tgroup cols="2">
13702      <thead>
13703       <row>
13704        <entry>Name</entry>
13705        <entry>Description</entry>
13706       </row>
13707      </thead>
13708
13709      <tbody>
13710
13711       <row>
13712        <entry><type>xmin</type></entry>
13713        <entry>
13714          Earliest transaction ID (txid) that is still active.  All earlier
13715          transactions will either be committed and visible, or rolled
13716          back and dead.
13717        </entry>
13718       </row>
13719
13720       <row>
13721        <entry><type>xmax</type></entry>
13722        <entry>
13723         First as-yet-unassigned txid.  All txids greater than or equal to this
13724         are not yet started as of the time of the snapshot, and thus invisible.
13725        </entry>
13726       </row>
13727
13728       <row>
13729        <entry><type>xip_list</type></entry>
13730        <entry>
13731         Active txids at the time of the snapshot.  The list
13732         includes only those active txids between <literal>xmin</>
13733         and <literal>xmax</>; there might be active txids higher
13734         than <literal>xmax</>.  A txid that is <literal>xmin &lt;= txid &lt;
13735         xmax</literal> and not in this list was already completed
13736         at the time of the snapshot, and thus either visible or
13737         dead according to its commit status.  The list does not
13738         include txids of subtransactions.
13739        </entry>
13740       </row>
13741
13742      </tbody>
13743     </tgroup>
13744    </table>
13745
13746    <para>
13747     <type>txid_snapshot</>'s textual representation is
13748     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
13749     For example <literal>10:20:10,14,15</literal> means
13750     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
13751    </para>
13752   </sect1>
13753
13754   <sect1 id="functions-admin">
13755    <title>System Administration Functions</title>
13756
13757    <para>
13758     <xref linkend="functions-admin-set-table"> shows the functions
13759     available to query and alter run-time configuration parameters.
13760    </para>
13761
13762    <table id="functions-admin-set-table">
13763     <title>Configuration Settings Functions</title>
13764     <tgroup cols="3">
13765      <thead>
13766       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
13767      </thead>
13768
13769      <tbody>
13770       <row>
13771        <entry>
13772         <indexterm>
13773          <primary>current_setting</primary>
13774         </indexterm>
13775         <literal><function>current_setting(<parameter>setting_name</parameter>)</function></literal>
13776        </entry>
13777        <entry><type>text</type></entry>
13778        <entry>get current value of setting</entry>
13779       </row>
13780       <row>
13781        <entry>
13782         <indexterm>
13783          <primary>set_config</primary>
13784         </indexterm>
13785         <literal><function>set_config(<parameter>setting_name</parameter>,
13786                              <parameter>new_value</parameter>,
13787                              <parameter>is_local</parameter>)</function></literal>
13788        </entry>
13789        <entry><type>text</type></entry>
13790        <entry>set parameter and return new value</entry>
13791       </row>
13792      </tbody>
13793     </tgroup>
13794    </table>
13795
13796    <indexterm>
13797     <primary>SET</primary>
13798    </indexterm>
13799
13800    <indexterm>
13801     <primary>SHOW</primary>
13802    </indexterm>
13803
13804    <indexterm>
13805     <primary>configuration</primary>
13806     <secondary sortas="server">of the server</secondary>
13807     <tertiary>functions</tertiary>
13808    </indexterm>
13809
13810    <para>
13811     The function <function>current_setting</function> yields the
13812     current value of the setting <parameter>setting_name</parameter>.
13813     It corresponds to the <acronym>SQL</acronym> command
13814     <command>SHOW</command>.  An example:
13815 <programlisting>
13816 SELECT current_setting('datestyle');
13817
13818  current_setting
13819 -----------------
13820  ISO, MDY
13821 (1 row)
13822 </programlisting>
13823    </para>
13824
13825    <para>
13826     <function>set_config</function> sets the parameter
13827     <parameter>setting_name</parameter> to
13828     <parameter>new_value</parameter>.  If
13829     <parameter>is_local</parameter> is <literal>true</literal>, the
13830     new value will only apply to the current transaction. If you want
13831     the new value to apply for the current session, use
13832     <literal>false</literal> instead. The function corresponds to the
13833     SQL command <command>SET</command>. An example:
13834 <programlisting>
13835 SELECT set_config('log_statement_stats', 'off', false);
13836
13837  set_config
13838 ------------
13839  off
13840 (1 row)
13841 </programlisting>
13842    </para>
13843
13844    <indexterm>
13845     <primary>pg_cancel_backend</primary>
13846    </indexterm>
13847    <indexterm>
13848     <primary>pg_reload_conf</primary>
13849    </indexterm>
13850    <indexterm>
13851     <primary>pg_rotate_logfile</primary>
13852    </indexterm>
13853    <indexterm>
13854     <primary>pg_terminate_backend</primary>
13855    </indexterm>
13856
13857    <indexterm>
13858     <primary>signal</primary>
13859     <secondary sortas="backend">backend processes</secondary>
13860    </indexterm>
13861
13862    <para>
13863     The functions shown in <xref
13864     linkend="functions-admin-signal-table"> send control signals to
13865     other server processes.  Use of these functions is restricted
13866     to superusers.
13867    </para>
13868
13869    <table id="functions-admin-signal-table">
13870     <title>Server Signalling Functions</title>
13871     <tgroup cols="3">
13872      <thead>
13873       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13874       </row>
13875      </thead>
13876
13877      <tbody>
13878       <row>
13879        <entry>
13880         <literal><function>pg_cancel_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
13881         </entry>
13882        <entry><type>boolean</type></entry>
13883        <entry>Cancel a backend's current query</entry>
13884       </row>
13885       <row>
13886        <entry>
13887         <literal><function>pg_reload_conf()</function></literal>
13888         </entry>
13889        <entry><type>boolean</type></entry>
13890        <entry>Cause server processes to reload their configuration files</entry>
13891       </row>
13892       <row>
13893        <entry>
13894         <literal><function>pg_rotate_logfile()</function></literal>
13895         </entry>
13896        <entry><type>boolean</type></entry>
13897        <entry>Rotate server's log file</entry>
13898       </row>
13899       <row>
13900        <entry>
13901         <literal><function>pg_terminate_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
13902         </entry>
13903        <entry><type>boolean</type></entry>
13904        <entry>Terminate a backend</entry>
13905       </row>
13906      </tbody>
13907     </tgroup>
13908    </table>
13909
13910    <para>
13911     Each of these functions returns <literal>true</literal> if
13912     successful and <literal>false</literal> otherwise.
13913    </para>
13914
13915    <para>
13916     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
13917     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
13918     respectively) to backend processes identified by process ID.
13919     The process ID of an active backend can be found from
13920     the <structfield>procpid</structfield> column of the
13921     <structname>pg_stat_activity</structname> view, or by listing the
13922     <command>postgres</command> processes on the server (using
13923     <application>ps</> on Unix or the <application>Task
13924     Manager</> on <productname>Windows</>).
13925    </para>
13926
13927    <para>
13928     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
13929     to the server, causing configuration files
13930     to be reloaded by all server processes.
13931    </para>
13932
13933    <para>
13934     <function>pg_rotate_logfile</> signals the log-file manager to switch
13935     to a new output file immediately.  This works only when the built-in
13936     log collector is running, since otherwise there is no log-file manager
13937     subprocess.
13938    </para>
13939
13940    <indexterm>
13941     <primary>backup</primary>
13942    </indexterm>
13943    <indexterm>
13944     <primary>pg_create_restore_point</primary>
13945    </indexterm>
13946    <indexterm>
13947     <primary>pg_current_xlog_insert_location</primary>
13948    </indexterm>
13949    <indexterm>
13950     <primary>pg_current_xlog_location</primary>
13951    </indexterm>
13952    <indexterm>
13953     <primary>pg_start_backup</primary>
13954    </indexterm>
13955    <indexterm>
13956     <primary>pg_stop_backup</primary>
13957    </indexterm>
13958    <indexterm>
13959     <primary>pg_switch_xlog</primary>
13960    </indexterm>
13961    <indexterm>
13962     <primary>pg_xlogfile_name</primary>
13963    </indexterm>
13964    <indexterm>
13965     <primary>pg_xlogfile_name_offset</primary>
13966    </indexterm>
13967
13968    <para>
13969     The functions shown in <xref
13970     linkend="functions-admin-backup-table"> assist in making on-line backups.
13971     These functions cannot be executed during recovery.
13972    </para>
13973
13974    <table id="functions-admin-backup-table">
13975     <title>Backup Control Functions</title>
13976     <tgroup cols="3">
13977      <thead>
13978       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13979       </row>
13980      </thead>
13981
13982      <tbody>
13983       <row>
13984        <entry>
13985         <literal><function>pg_create_restore_point(<parameter>name</> <type>text</>)</function></literal>
13986         </entry>
13987        <entry><type>text</type></entry>
13988        <entry>Create a named point for performing restore (restricted to superusers)</entry>
13989       </row>
13990       <row>
13991        <entry>
13992         <literal><function>pg_current_xlog_insert_location()</function></literal>
13993         </entry>
13994        <entry><type>text</type></entry>
13995        <entry>Get current transaction log insert location</entry>
13996       </row>
13997       <row>
13998        <entry>
13999         <literal><function>pg_current_xlog_location()</function></literal>
14000         </entry>
14001        <entry><type>text</type></entry>
14002        <entry>Get current transaction log write location</entry>
14003       </row>
14004       <row>
14005        <entry>
14006         <literal><function>pg_start_backup(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> </optional>)</function></literal>
14007         </entry>
14008        <entry><type>text</type></entry>
14009        <entry>Prepare for performing on-line backup (restricted to superusers or replication roles)</entry>
14010       </row>
14011       <row>
14012        <entry>
14013         <literal><function>pg_stop_backup()</function></literal>
14014         </entry>
14015        <entry><type>text</type></entry>
14016        <entry>Finish performing on-line backup (restricted to superusers or replication roles)</entry>
14017       </row>
14018       <row>
14019        <entry>
14020         <literal><function>pg_switch_xlog()</function></literal>
14021         </entry>
14022        <entry><type>text</type></entry>
14023        <entry>Force switch to a new transaction log file (restricted to superusers)</entry>
14024       </row>
14025       <row>
14026        <entry>
14027         <literal><function>pg_xlogfile_name(<parameter>location</> <type>text</>)</function></literal>
14028         </entry>
14029        <entry><type>text</type></entry>
14030        <entry>Convert transaction log location string to file name</entry>
14031       </row>
14032       <row>
14033        <entry>
14034         <literal><function>pg_xlogfile_name_offset(<parameter>location</> <type>text</>)</function></literal>
14035         </entry>
14036        <entry><type>text</>, <type>integer</></entry>
14037        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
14038       </row>
14039      </tbody>
14040     </tgroup>
14041    </table>
14042
14043    <para>
14044     <function>pg_start_backup</> accepts an
14045     arbitrary user-defined label for the backup.  (Typically this would be
14046     the name under which the backup dump file will be stored.)  The function
14047     writes a backup label file (<filename>backup_label</>) into the
14048     database cluster's data directory, performs a checkpoint,
14049     and then returns the backup's starting transaction log location as text.
14050     The user can ignore this result value, but it is
14051     provided in case it is useful.
14052 <programlisting>
14053 postgres=# select pg_start_backup('label_goes_here');
14054  pg_start_backup
14055 -----------------
14056  0/D4445B8
14057 (1 row)
14058 </programlisting>
14059     There is an optional second parameter of type <type>boolean</type>.  If <literal>true</>,
14060     it specifies executing <function>pg_start_backup</> as quickly as
14061     possible.  This forces an immediate checkpoint which will cause a
14062     spike in I/O operations, slowing any concurrently executing queries.
14063    </para>
14064
14065    <para>
14066     <function>pg_stop_backup</> removes the label file created by
14067     <function>pg_start_backup</>, and creates a backup history file in
14068     the transaction log archive area.  The history file includes the label given to
14069     <function>pg_start_backup</>, the starting and ending transaction log locations for
14070     the backup, and the starting and ending times of the backup.  The return
14071     value is the backup's ending transaction log location (which again
14072     can be ignored).  After recording the ending location, the current
14073     transaction log insertion
14074     point is automatically advanced to the next transaction log file, so that the
14075     ending transaction log file can be archived immediately to complete the backup.
14076    </para>
14077
14078    <para>
14079     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the
14080     current file to be archived (assuming you are using continuous archiving).
14081     The return value is the ending transaction log location + 1 within the just-completed transaction log file.
14082     If there has been no transaction log activity since the last transaction log switch,
14083     <function>pg_switch_xlog</> does nothing and returns the start location
14084     of the transaction log file currently in use.
14085    </para>
14086
14087    <para>
14088     <function>pg_create_restore_point</> creates a named transaction log
14089     record that can be used as recovery target, and returns the corresponding
14090     transaction log location.  The given name can then be used with
14091     <xref linkend="recovery-target-name"> to specify the point up to which
14092     recovery will proceed.  Avoid creating multiple restore points with the
14093     same name, since recovery will stop at the first one whose name matches
14094     the recovery target.
14095    </para>
14096
14097    <para>
14098     <function>pg_current_xlog_location</> displays the current transaction log write
14099     location in the same format used by the above functions.  Similarly,
14100     <function>pg_current_xlog_insert_location</> displays the current transaction log
14101     insertion point.  The insertion point is the <quote>logical</> end
14102     of the transaction log
14103     at any instant, while the write location is the end of what has actually
14104     been written out from the server's internal buffers.  The write location
14105     is the end of what can be examined from outside the server, and is usually
14106     what you want if you are interested in archiving partially-complete transaction log
14107     files.  The insertion point is made available primarily for server
14108     debugging purposes.  These are both read-only operations and do not
14109     require superuser permissions.
14110    </para>
14111
14112    <para>
14113     You can use <function>pg_xlogfile_name_offset</> to extract the
14114     corresponding transaction log file name and byte offset from the results of any of the
14115     above functions.  For example:
14116 <programlisting>
14117 postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup());
14118         file_name         | file_offset 
14119 --------------------------+-------------
14120  00000001000000000000000D |     4039624
14121 (1 row)
14122 </programlisting>
14123     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
14124     When the given transaction log location is exactly at a transaction log file boundary, both
14125     these functions return the name of the preceding transaction log file.
14126     This is usually the desired behavior for managing transaction log archiving
14127     behavior, since the preceding file is the last one that currently
14128     needs to be archived.
14129    </para>
14130
14131    <para>
14132     For details about proper usage of these functions, see
14133     <xref linkend="continuous-archiving">.
14134    </para>
14135
14136    <indexterm>
14137     <primary>pg_is_in_recovery</primary>
14138    </indexterm>
14139    <indexterm>
14140     <primary>pg_last_xlog_receive_location</primary>
14141    </indexterm>
14142    <indexterm>
14143     <primary>pg_last_xlog_replay_location</primary>
14144    </indexterm>
14145    <indexterm>
14146     <primary>pg_last_xact_replay_timestamp</primary>
14147    </indexterm>
14148
14149    <para>
14150     The functions shown in <xref
14151     linkend="functions-recovery-info-table"> provide information
14152     about the current status of the standby.
14153     These functions may be executed during both recovery and in normal running.
14154    </para>
14155
14156    <table id="functions-recovery-info-table">
14157     <title>Recovery Information Functions</title>
14158     <tgroup cols="3">
14159      <thead>
14160       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14161       </row>
14162      </thead>
14163
14164      <tbody>
14165       <row>
14166        <entry>
14167         <literal><function>pg_is_in_recovery()</function></literal>
14168         </entry>
14169        <entry><type>bool</type></entry>
14170        <entry>True if recovery is still in progress.
14171        </entry>
14172       </row>
14173       <row>
14174        <entry>
14175         <literal><function>pg_last_xlog_receive_location()</function></literal>
14176         </entry>
14177        <entry><type>text</type></entry>
14178        <entry>Get last transaction log location received and synced to disk by
14179         streaming replication. While streaming replication is in progress
14180         this will increase monotonically. If recovery has completed this will
14181         remain static at
14182         the value of the last WAL record received and synced to disk during
14183         recovery. If streaming replication is disabled, or if it has not yet
14184         started, the function returns NULL.
14185        </entry>
14186       </row>
14187       <row>
14188        <entry>
14189         <literal><function>pg_last_xlog_replay_location()</function></literal>
14190         </entry>
14191        <entry><type>text</type></entry>
14192        <entry>Get last transaction log location replayed during recovery.
14193         If recovery is still in progress this will increase monotonically.
14194         If recovery has completed then this value will remain static at
14195         the value of the last WAL record applied during that recovery.
14196         When the server has been started normally without recovery
14197         the function returns NULL.
14198        </entry>
14199       </row>
14200       <row>
14201        <entry>
14202         <literal><function>pg_last_xact_replay_timestamp()</function></literal>
14203         </entry>
14204        <entry><type>timestamp with time zone</type></entry>
14205        <entry>Get timestamp of last transaction replayed during recovery.
14206         This is the time at which the commit or abort WAL record for that
14207         transaction was generated.
14208         If no transactions have been replayed during recovery, this function
14209         returns NULL.  Otherwise, if recovery is still in progress this will
14210         increase monotonically.  If recovery has completed then this value will
14211         remain static at the value of the last transaction applied during that
14212         recovery.  When the server has been started normally without recovery
14213         the function returns NULL.
14214        </entry>
14215       </row>
14216      </tbody>
14217     </tgroup>
14218    </table>
14219
14220    <indexterm>
14221     <primary>pg_is_xlog_replay_paused</primary>
14222    </indexterm>
14223    <indexterm>
14224     <primary>pg_xlog_replay_pause</primary>
14225    </indexterm>
14226    <indexterm>
14227     <primary>pg_xlog_replay_resume</primary>
14228    </indexterm>
14229
14230    <para>
14231     The functions shown in <xref
14232     linkend="functions-recovery-control-table"> control the progress of recovery.
14233     These functions may be executed only during recovery.
14234    </para>
14235
14236    <table id="functions-recovery-control-table">
14237     <title>Recovery Control Functions</title>
14238     <tgroup cols="3">
14239      <thead>
14240       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14241       </row>
14242      </thead>
14243
14244      <tbody>
14245       <row>
14246        <entry>
14247         <literal><function>pg_is_xlog_replay_paused()</function></literal>
14248         </entry>
14249        <entry><type>bool</type></entry>
14250        <entry>True if recovery is paused.
14251        </entry>
14252       </row>
14253       <row>
14254        <entry>
14255         <literal><function>pg_xlog_replay_pause()</function></literal>
14256         </entry>
14257        <entry><type>void</type></entry>
14258        <entry>Pauses recovery immediately.
14259        </entry>
14260       </row>
14261       <row>
14262        <entry>
14263         <literal><function>pg_xlog_replay_resume()</function></literal>
14264         </entry>
14265        <entry><type>void</type></entry>
14266        <entry>Restarts recovery if it was paused.
14267        </entry>
14268       </row>
14269      </tbody>
14270     </tgroup>
14271    </table>
14272
14273    <para>
14274     While recovery is paused no further database changes are applied.
14275     If in hot standby, all new queries will see the same consistent snapshot
14276     of the database, and no further query conflicts will be generated until
14277     recovery is resumed.
14278    </para>
14279
14280    <para>
14281     If streaming replication is disabled, the paused state may continue
14282     indefinitely without problem. While streaming replication is in
14283     progress WAL records will continue to be received, which will
14284     eventually fill available disk space, depending upon the duration of
14285     the pause, the rate of WAL generation and available disk space.
14286    </para>
14287
14288    <para>
14289     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
14290     the disk space usage of database objects.
14291    </para>
14292
14293    <indexterm>
14294     <primary>pg_column_size</primary>
14295    </indexterm>
14296    <indexterm>
14297     <primary>pg_database_size</primary>
14298    </indexterm>
14299    <indexterm>
14300     <primary>pg_indexes_size</primary>
14301    </indexterm>
14302    <indexterm>
14303     <primary>pg_relation_size</primary>
14304    </indexterm>
14305    <indexterm>
14306     <primary>pg_size_pretty</primary>
14307    </indexterm>
14308    <indexterm>
14309     <primary>pg_table_size</primary>
14310    </indexterm>
14311    <indexterm>
14312     <primary>pg_tablespace_size</primary>
14313    </indexterm>
14314    <indexterm>
14315     <primary>pg_total_relation_size</primary>
14316    </indexterm>
14317
14318    <table id="functions-admin-dbsize">
14319     <title>Database Object Size Functions</title>
14320     <tgroup cols="3">
14321      <thead>
14322       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14323       </row>
14324      </thead>
14325
14326      <tbody>
14327       <row>
14328        <entry><literal><function>pg_column_size(<type>any</type>)</function></literal></entry>
14329        <entry><type>int</type></entry>
14330        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
14331       </row>
14332       <row>
14333        <entry>
14334         <literal><function>pg_database_size(<type>oid</type>)</function></literal>
14335         </entry>
14336        <entry><type>bigint</type></entry>
14337        <entry>Disk space used by the database with the specified OID</entry>
14338       </row>
14339       <row>
14340        <entry>
14341         <literal><function>pg_database_size(<type>name</type>)</function></literal>
14342         </entry>
14343        <entry><type>bigint</type></entry>
14344        <entry>Disk space used by the database with the specified name</entry>
14345       </row>
14346       <row>
14347        <entry>
14348         <literal><function>pg_indexes_size(<type>regclass</type>)</function></literal>
14349         </entry>
14350        <entry><type>bigint</type></entry>
14351        <entry>
14352         Total disk space used by indexes attached to the specified table
14353        </entry>
14354       </row>
14355       <row>
14356        <entry>
14357         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</function></literal>
14358         </entry>
14359        <entry><type>bigint</type></entry>
14360        <entry>
14361         Disk space used by the specified fork (<literal>'main'</literal>,
14362         <literal>'fsm'</literal> or <literal>'vm'</>)
14363         of the specified table or index
14364        </entry>
14365       </row>
14366       <row>
14367        <entry>
14368         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
14369         </entry>
14370        <entry><type>bigint</type></entry>
14371        <entry>
14372         Shorthand for <literal>pg_relation_size(..., 'main')</literal>
14373        </entry>
14374       </row>
14375       <row>
14376        <entry>
14377         <literal><function>pg_size_pretty(<type>bigint</type>)</function></literal>
14378         </entry>
14379        <entry><type>text</type></entry>
14380        <entry>Converts a size in bytes into a human-readable format with size units</entry>
14381       </row>
14382       <row>
14383        <entry>
14384         <literal><function>pg_table_size(<type>regclass</type>)</function></literal>
14385         </entry>
14386        <entry><type>bigint</type></entry>
14387        <entry>
14388         Disk space used by the specified table, excluding indexes
14389         (but including TOAST, free space map, and visibility map)
14390        </entry>
14391       </row>
14392       <row>
14393        <entry>
14394         <literal><function>pg_tablespace_size(<type>oid</type>)</function></literal>
14395         </entry>
14396        <entry><type>bigint</type></entry>
14397        <entry>Disk space used by the tablespace with the specified OID</entry>
14398       </row>
14399       <row>
14400        <entry>
14401         <literal><function>pg_tablespace_size(<type>name</type>)</function></literal>
14402         </entry>
14403        <entry><type>bigint</type></entry>
14404        <entry>Disk space used by the tablespace with the specified name</entry>
14405       </row>
14406       <row>
14407        <entry>
14408         <literal><function>pg_total_relation_size(<type>regclass</type>)</function></literal>
14409         </entry>
14410        <entry><type>bigint</type></entry>
14411        <entry>
14412         Total disk space used by the specified table,
14413         including all indexes and <acronym>TOAST</> data
14414        </entry>
14415       </row>
14416      </tbody>
14417     </tgroup>
14418    </table>
14419
14420    <para>
14421     <function>pg_column_size</> shows the space used to store any individual
14422     data value.
14423    </para>
14424
14425    <para>
14426     <function>pg_total_relation_size</> accepts the OID or name of a
14427     table or toast table, and returns the total on-disk space used for
14428     that table, including all associated indexes.  This function is
14429     equivalent to <function>pg_table_size</function>
14430     <literal>+</> <function>pg_indexes_size</function>.
14431    </para>
14432
14433    <para>
14434     <function>pg_table_size</> accepts the OID or name of a table and
14435     returns the disk space needed for that table, exclusive of indexes.
14436     (TOAST space, free space map, and visibility map are included.)
14437    </para>
14438
14439    <para>
14440     <function>pg_indexes_size</> accepts the OID or name of a table and
14441     returns the total disk space used by all the indexes attached to that
14442     table.
14443    </para>
14444
14445    <para>
14446     <function>pg_database_size</function> and <function>pg_tablespace_size</>
14447     accept the OID or name of a database or tablespace, and return the total
14448     disk space used therein.
14449    </para>
14450
14451    <para>
14452     <function>pg_relation_size</> accepts the OID or name of a table, index or
14453     toast table, and returns the on-disk size in bytes. Specifying
14454     <literal>'main'</literal> or leaving out the second argument returns the
14455     size of the main data fork of the relation. Specifying
14456     <literal>'fsm'</literal> returns the size of the
14457     Free Space Map (see <xref linkend="storage-fsm">) associated with the
14458     relation. Specifying <literal>'vm'</literal> returns the size of the
14459     Visibility Map (see <xref linkend="storage-vm">) associated with the
14460     relation.  Note that this function shows the size of only one fork;
14461     for most purposes it is more convenient to use the higher-level
14462     functions <function>pg_total_relation_size</> or
14463     <function>pg_table_size</>.
14464    </para>
14465
14466    <para>
14467     <function>pg_size_pretty</> can be used to format the result of one of
14468     the other functions in a human-readable way, using kB, MB, GB or TB as
14469     appropriate.
14470    </para>
14471
14472    <para>
14473     The functions above that operate on tables or indexes accept a
14474     <type>regclass</> argument, which is simply the OID of the table or index
14475     in the <structname>pg_class</> system catalog.  You do not have to look up
14476     the OID by hand, however, since the <type>regclass</> data type's input
14477     converter will do the work for you.  Just write the table name enclosed in
14478     single quotes so that it looks like a literal constant.  For compatibility
14479     with the handling of ordinary <acronym>SQL</acronym> names, the string
14480     will be converted to lower case unless it contains double quotes around
14481     the table name.
14482    </para>
14483
14484    <para>
14485     The functions shown in <xref linkend="functions-admin-dblocation"> assist
14486     in identifying the specific disk files associated with database objects.
14487    </para>
14488
14489    <indexterm>
14490     <primary>pg_relation_filenode</primary>
14491    </indexterm>
14492    <indexterm>
14493     <primary>pg_relation_filepath</primary>
14494    </indexterm>
14495
14496    <table id="functions-admin-dblocation">
14497     <title>Database Object Location Functions</title>
14498     <tgroup cols="3">
14499      <thead>
14500       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14501       </row>
14502      </thead>
14503
14504      <tbody>
14505       <row>
14506        <entry>
14507         <literal><function>pg_relation_filenode(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
14508         </entry>
14509        <entry><type>oid</type></entry>
14510        <entry>
14511         Filenode number of the specified relation
14512        </entry>
14513       </row>
14514       <row>
14515        <entry>
14516         <literal><function>pg_relation_filepath(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
14517         </entry>
14518        <entry><type>text</type></entry>
14519        <entry>
14520         File path name of the specified relation
14521        </entry>
14522       </row>
14523      </tbody>
14524     </tgroup>
14525    </table>
14526
14527    <para>
14528     <function>pg_relation_filenode</> accepts the OID or name of a table,
14529     index, sequence, or toast table, and returns the <quote>filenode</> number
14530     currently assigned to it.  The filenode is the base component of the file
14531     name(s) used for the relation (see <xref linkend="storage-file-layout">
14532     for more information).  For most tables the result is the same as
14533     <structname>pg_class</>.<structfield>relfilenode</>, but for certain
14534     system catalogs <structfield>relfilenode</> is zero and this function must
14535     be used to get the correct value.  The function returns NULL if passed
14536     a relation that does not have storage, such as a view.
14537    </para>
14538
14539    <para>
14540     <function>pg_relation_filepath</> is similar to
14541     <function>pg_relation_filenode</>, but it returns the entire file path name
14542     (relative to the database cluster's data directory <varname>PGDATA</>) of
14543     the relation.
14544    </para>
14545
14546    <para>
14547     The functions shown in <xref
14548     linkend="functions-admin-genfile"> provide native access to
14549     files on the machine hosting the server. Only files within the
14550     database cluster directory and the <varname>log_directory</> can be
14551     accessed.  Use a relative path for files in the cluster directory,
14552     and a path matching the <varname>log_directory</> configuration setting
14553     for log files.  Use of these functions is restricted to superusers.
14554    </para>
14555
14556    <table id="functions-admin-genfile">
14557     <title>Generic File Access Functions</title>
14558     <tgroup cols="3">
14559      <thead>
14560       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14561       </row>
14562      </thead>
14563
14564      <tbody>
14565       <row>
14566        <entry>
14567         <literal><function>pg_ls_dir(<parameter>dirname</> <type>text</>)</function></literal>
14568        </entry>
14569        <entry><type>setof text</type></entry>
14570        <entry>List the contents of a directory</entry>
14571       </row>
14572       <row>
14573        <entry>
14574         <literal><function>pg_read_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
14575        </entry>
14576        <entry><type>text</type></entry>
14577        <entry>Return the contents of a text file</entry>
14578       </row>
14579       <row>
14580        <entry>
14581         <literal><function>pg_read_binary_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
14582        </entry>
14583        <entry><type>bytea</type></entry>
14584        <entry>Return the contents of a file</entry>
14585       </row>
14586       <row>
14587        <entry>
14588         <literal><function>pg_stat_file(<parameter>filename</> <type>text</>)</function></literal>
14589        </entry>
14590        <entry><type>record</type></entry>
14591        <entry>Return information about a file</entry>
14592       </row>
14593      </tbody>
14594     </tgroup>
14595    </table>
14596
14597    <indexterm>
14598     <primary>pg_ls_dir</primary>
14599    </indexterm>
14600    <para>
14601     <function>pg_ls_dir</> returns all the names in the specified
14602     directory, except the special entries <quote><literal>.</></> and
14603     <quote><literal>..</></>.
14604    </para>
14605
14606    <indexterm>
14607     <primary>pg_read_file</primary>
14608    </indexterm>
14609    <para>
14610     <function>pg_read_file</> returns part of a text file, starting
14611     at the given <parameter>offset</>, returning at most <parameter>length</>
14612     bytes (less if the end of file is reached first).  If <parameter>offset</>
14613     is negative, it is relative to the end of the file.
14614     If <parameter>offset</> and <parameter>length</> are omitted, the entire
14615     file is returned.  The bytes read from the file are interpreted as a string
14616     in the server encoding; an error is thrown if they are not valid in that
14617     encoding.
14618    </para>
14619
14620    <indexterm>
14621     <primary>pg_read_binary_file</primary>
14622    </indexterm>
14623    <para>
14624     <function>pg_read_binary_file</> is similar to
14625     <function>pg_read_file</>, except that the result is a bytea value;
14626     accordingly, no encoding checks are performed.
14627     In combination with the <function>convert_from</> function, this function
14628     can be used to read a file in a specified encoding:
14629 <programlisting>
14630 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
14631 </programlisting>
14632    </para>
14633
14634    <indexterm>
14635     <primary>pg_stat_file</primary>
14636    </indexterm>
14637    <para>
14638     <function>pg_stat_file</> returns a record containing the file
14639     size, last accessed time stamp, last modified time stamp,
14640     last file status change time stamp (Unix platforms only),
14641     file creation time stamp (Windows only), and a <type>boolean</type>
14642     indicating if it is a directory.  Typical usages include:
14643 <programlisting>
14644 SELECT * FROM pg_stat_file('filename');
14645 SELECT (pg_stat_file('filename')).modification;
14646 </programlisting>
14647    </para>
14648
14649    <para>
14650     The functions shown in <xref linkend="functions-advisory-locks"> manage
14651     advisory locks.  For details about proper use of these functions, see
14652     <xref linkend="advisory-locks">.
14653    </para>
14654
14655    <table id="functions-advisory-locks">
14656     <title>Advisory Lock Functions</title>
14657     <tgroup cols="3">
14658      <thead>
14659       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
14660       </row>
14661      </thead>
14662
14663      <tbody>
14664       <row>
14665        <entry>
14666         <literal><function>pg_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
14667        </entry>
14668        <entry><type>void</type></entry>
14669        <entry>Obtain exclusive session level advisory lock</entry>
14670       </row>
14671       <row>
14672        <entry>
14673         <literal><function>pg_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14674        </entry>
14675        <entry><type>void</type></entry>
14676        <entry>Obtain exclusive session level advisory lock</entry>
14677       </row>
14678       <row>
14679        <entry>
14680         <literal><function>pg_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14681        </entry>
14682        <entry><type>void</type></entry>
14683        <entry>Obtain shared session level advisory lock</entry>
14684       </row>
14685       <row>
14686        <entry>
14687         <literal><function>pg_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14688        </entry>
14689        <entry><type>void</type></entry>
14690        <entry>Obtain shared session level advisory lock</entry>
14691       </row>
14692       <row>
14693        <entry>
14694         <literal><function>pg_advisory_unlock(<parameter>key</> <type>bigint</>)</function></literal>
14695        </entry>
14696        <entry><type>boolean</type></entry>
14697        <entry>Release an exclusive session level advisory lock</entry>
14698       </row>
14699       <row>
14700        <entry>
14701         <literal><function>pg_advisory_unlock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14702        </entry>
14703        <entry><type>boolean</type></entry>
14704        <entry>Release an exclusive session level advisory lock</entry>
14705       </row>
14706       <row>
14707        <entry>
14708         <literal><function>pg_advisory_unlock_all()</function></literal>
14709        </entry>
14710        <entry><type>void</type></entry>
14711        <entry>Release all session level advisory locks held by the current session</entry>
14712       </row>
14713       <row>
14714        <entry>
14715         <literal><function>pg_advisory_unlock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14716        </entry>
14717        <entry><type>boolean</type></entry>
14718        <entry>Release a shared session level advisory lock</entry>
14719       </row>
14720       <row>
14721        <entry>
14722         <literal><function>pg_advisory_unlock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14723        </entry>
14724        <entry><type>boolean</type></entry>
14725        <entry>Release a shared session level advisory lock</entry>
14726       </row>
14727       <row>
14728        <entry>
14729         <literal><function>pg_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
14730        </entry>
14731        <entry><type>void</type></entry>
14732        <entry>Obtain exclusive transaction level advisory lock</entry>
14733       </row>
14734       <row>
14735        <entry>
14736         <literal><function>pg_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14737        </entry>
14738        <entry><type>void</type></entry>
14739        <entry>Obtain exclusive transaction level advisory lock</entry>
14740       </row>
14741       <row>
14742        <entry>
14743         <literal><function>pg_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14744        </entry>
14745        <entry><type>void</type></entry>
14746        <entry>Obtain shared transaction level advisory lock</entry>
14747       </row>
14748       <row>
14749        <entry>
14750         <literal><function>pg_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14751        </entry>
14752        <entry><type>void</type></entry>
14753        <entry>Obtain shared advisory lock for the current transaction</entry>
14754       </row>
14755       <row>
14756        <entry>
14757         <literal><function>pg_try_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
14758        </entry>
14759        <entry><type>boolean</type></entry>
14760        <entry>Obtain exclusive session level advisory lock if available</entry>
14761       </row>
14762       <row>
14763        <entry>
14764         <literal><function>pg_try_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14765        </entry>
14766        <entry><type>boolean</type></entry>
14767        <entry>Obtain exclusive session level advisory lock if available</entry>
14768       </row>
14769       <row>
14770        <entry>
14771         <literal><function>pg_try_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14772        </entry>
14773        <entry><type>boolean</type></entry>
14774        <entry>Obtain shared session level advisory lock if available</entry>
14775       </row>
14776       <row>
14777        <entry>
14778         <literal><function>pg_try_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14779        </entry>
14780        <entry><type>boolean</type></entry>
14781        <entry>Obtain shared session level advisory lock if available</entry>
14782       </row>
14783       <row>
14784        <entry>
14785         <literal><function>pg_try_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
14786        </entry>
14787        <entry><type>boolean</type></entry>
14788        <entry>Obtain exclusive transaction level advisory lock if available</entry>
14789       </row>
14790       <row>
14791        <entry>
14792         <literal><function>pg_try_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14793        </entry>
14794        <entry><type>boolean</type></entry>
14795        <entry>Obtain exclusive transaction level advisory lock if available</entry>
14796       </row>
14797       <row>
14798        <entry>
14799         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
14800        </entry>
14801        <entry><type>boolean</type></entry>
14802        <entry>Obtain shared transaction level advisory lock if available</entry>
14803       </row>
14804       <row>
14805        <entry>
14806         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
14807        </entry>
14808        <entry><type>boolean</type></entry>
14809        <entry>Obtain shared transaction level advisory lock if available</entry>
14810       </row>
14811      </tbody>
14812     </tgroup>
14813    </table>
14814
14815    <indexterm>
14816     <primary>pg_advisory_lock</primary>
14817    </indexterm>
14818    <para>
14819     <function>pg_advisory_lock</> locks an application-defined resource,
14820     which can be identified either by a single 64-bit key value or two
14821     32-bit key values (note that these two key spaces do not overlap).
14822     The key type is specified in <literal>pg_locks.objid</>.  If
14823     another session already holds a lock on the same resource, the
14824     function will wait until the resource becomes available.  The lock
14825     is exclusive.  Multiple lock requests stack, so that if the same resource
14826     is locked three times it must be also unlocked three times to be
14827     released for other sessions' use.
14828    </para>
14829
14830    <indexterm>
14831     <primary>pg_advisory_lock_shared</primary>
14832    </indexterm>
14833    <para>
14834     <function>pg_advisory_lock_shared</> works the same as
14835     <function>pg_advisory_lock</>,
14836     except the lock can be shared with other sessions requesting shared locks.
14837     Only would-be exclusive lockers are locked out.
14838    </para>
14839
14840    <indexterm>
14841     <primary>pg_try_advisory_lock</primary>
14842    </indexterm>
14843    <para>
14844     <function>pg_try_advisory_lock</> is similar to
14845     <function>pg_advisory_lock</>, except the function will not wait for the
14846     lock to become available.  It will either obtain the lock immediately and
14847     return <literal>true</>, or return <literal>false</> if the lock cannot be
14848     acquired immediately.
14849    </para>
14850
14851    <indexterm>
14852     <primary>pg_try_advisory_lock_shared</primary>
14853    </indexterm>
14854    <para>
14855     <function>pg_try_advisory_lock_shared</> works the same as
14856     <function>pg_try_advisory_lock</>, except it attempts to acquire
14857     a shared rather than an exclusive lock.
14858    </para>
14859
14860    <indexterm>
14861     <primary>pg_advisory_xact_lock</primary>
14862    </indexterm>
14863    <para>
14864     <function>pg_advisory_xact_lock</> works the same as
14865     <function>pg_advisory_lock</>, expect the lock is automatically released
14866     at the end of the current transaction and can not be released explicitly.
14867    </para>
14868
14869    <indexterm>
14870     <primary>pg_advisory_xact_lock_shared</primary>
14871    </indexterm>
14872    <para>
14873     <function>pg_advisory_xact_lock_shared</> works the same as
14874     <function>pg_advisory_lock_shared</>, expect the lock is automatically released
14875     at the end of the current transaction and can not be released explicitly.
14876    </para>
14877
14878    <indexterm>
14879     <primary>pg_try_advisory_xact_lock</primary>
14880    </indexterm>
14881    <para>
14882     <function>pg_try_advisory_xact_lock</> works the same as
14883     <function>pg_try_advisory_lock</>, expect the lock, if acquired,
14884     is automatically released at the end of the current transaction and
14885     can not be released explicitly.
14886    </para>
14887
14888    <indexterm>
14889     <primary>pg_try_advisory_xact_lock_shared</primary>
14890    </indexterm>
14891    <para>
14892     <function>pg_try_advisory_xact_lock_shared</> works the same as
14893     <function>pg_try_advisory_lock_shared</>, expect the lock, if acquired,
14894     is automatically released at the end of the current transaction and
14895     can not be released explicitly.
14896    </para>
14897
14898    <indexterm>
14899     <primary>pg_advisory_unlock</primary>
14900    </indexterm>
14901    <para>
14902     <function>pg_advisory_unlock</> will release a previously-acquired
14903     exclusive session level advisory lock.  It
14904     returns <literal>true</> if the lock is successfully released.
14905     If the lock was not held, it will return <literal>false</>,
14906     and in addition, an SQL warning will be raised by the server.
14907    </para>
14908
14909    <indexterm>
14910     <primary>pg_advisory_unlock_shared</primary>
14911    </indexterm>
14912    <para>
14913     <function>pg_advisory_unlock_shared</> works the same as
14914     <function>pg_advisory_unlock</>,
14915     except it releases a shared session level advisory lock.
14916    </para>
14917
14918    <indexterm>
14919     <primary>pg_advisory_unlock_all</primary>
14920    </indexterm>
14921    <para>
14922     <function>pg_advisory_unlock_all</> will release all session level advisory
14923     locks held by the current session.  (This function is implicitly invoked
14924     at session end, even if the client disconnects ungracefully.)
14925    </para>
14926
14927   </sect1>
14928
14929   <sect1 id="functions-trigger">
14930    <title>Trigger Functions</title>
14931
14932    <indexterm>
14933      <primary>suppress_redundant_updates_trigger</primary>
14934    </indexterm>
14935
14936    <para>
14937       Currently <productname>PostgreSQL</> provides one built in trigger
14938       function, <function>suppress_redundant_updates_trigger</>,
14939       which will prevent any update
14940       that does not actually change the data in the row from taking place, in
14941       contrast to the normal behavior which always performs the update
14942       regardless of whether or not the data has changed. (This normal behavior
14943       makes updates run faster, since no checking is required, and is also
14944       useful in certain cases.)
14945     </para>
14946
14947     <para>
14948       Ideally, you should normally avoid running updates that don't actually
14949       change the data in the record. Redundant updates can cost considerable
14950       unnecessary time, especially if there are lots of indexes to alter,
14951       and space in dead rows that will eventually have to be vacuumed.
14952       However, detecting such situations in client code is not
14953       always easy, or even possible, and writing expressions to detect
14954       them can be error-prone. An alternative is to use
14955       <function>suppress_redundant_updates_trigger</>, which will skip
14956       updates that don't change the data. You should use this with care,
14957       however. The trigger takes a small but non-trivial time for each record,
14958       so if most of the records affected by an update are actually changed,
14959       use of this trigger will actually make the update run slower.
14960     </para>
14961
14962     <para>
14963       The <function>suppress_redundant_updates_trigger</> function can be
14964       added to a table like this:
14965 <programlisting>
14966 CREATE TRIGGER z_min_update
14967 BEFORE UPDATE ON tablename
14968 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
14969 </programlisting>
14970       In most cases, you would want to fire this trigger last for each row.
14971       Bearing in mind that triggers fire in name order, you would then
14972       choose a trigger name that comes after the name of any other trigger
14973       you might have on the table.
14974     </para>
14975     <para>
14976        For more information about creating triggers, see
14977         <xref linkend="SQL-CREATETRIGGER">.
14978     </para>
14979   </sect1>
14980 </chapter>