]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
Document that chr(0) is not supported, and why.
[postgresql] / doc / src / sgml / func.sgml
1 <!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.421 2008/03/03 17:11:13 momjian Exp $ -->
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 show the list of all actually
21    available functions and operators, respectively.
22   </para>
23
24   <para>
25    If you are concerned about portability then take 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 the 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 data types where this
251     makes sense.  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     Similarly,
272 <synopsis>
273 <replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
274 </synopsis>
275     is equivalent to
276 <synopsis>
277 <replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
278 </synopsis>
279     There is no difference between the two respective forms apart from
280     the <acronym>CPU</acronym> cycles required to rewrite the first one
281     into the second one internally.
282     <indexterm>
283      <primary>BETWEEN SYMMETRIC</primary>
284     </indexterm>
285     <token>BETWEEN SYMMETRIC</> is the same as <literal>BETWEEN</>
286     except there is no requirement that the argument to the left of <literal>AND</> be less than
287     or equal to the argument on the right;  the proper range is automatically determined.
288    </para>
289
290    <para>
291     <indexterm>
292      <primary>IS NULL</primary>
293     </indexterm>
294     <indexterm>
295      <primary>IS NOT NULL</primary>
296     </indexterm>
297     <indexterm>
298      <primary>ISNULL</primary>
299     </indexterm>
300     <indexterm>
301      <primary>NOTNULL</primary>
302     </indexterm>
303     To check whether a value is or is not null, use the constructs
304 <synopsis>
305 <replaceable>expression</replaceable> IS NULL
306 <replaceable>expression</replaceable> IS NOT NULL
307 </synopsis>
308     or the equivalent, but nonstandard, constructs
309 <synopsis>
310 <replaceable>expression</replaceable> ISNULL
311 <replaceable>expression</replaceable> NOTNULL
312 </synopsis>
313     <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
314    </para>
315
316    <para>
317     Do <emphasis>not</emphasis> write
318     <literal><replaceable>expression</replaceable> = NULL</literal>
319     because <literal>NULL</> is not <quote>equal to</quote>
320     <literal>NULL</>.  (The null value represents an unknown value,
321     and it is not known whether two unknown values are equal.) This
322     behavior conforms to the SQL standard.
323    </para>
324
325   <tip>
326    <para>
327     Some applications might expect that
328     <literal><replaceable>expression</replaceable> = NULL</literal>
329     returns true if <replaceable>expression</replaceable> evaluates to
330     the null value.  It is highly recommended that these applications
331     be modified to comply with the SQL standard. However, if that
332     cannot be done the <xref linkend="guc-transform-null-equals">
333     configuration variable is available. If it is enabled,
334     <productname>PostgreSQL</productname> will convert <literal>x =
335     NULL</literal> clauses to <literal>x IS NULL</literal>.  This was
336     the default behavior in <productname>PostgreSQL</productname>
337     releases 6.5 through 7.1.
338    </para>
339   </tip>
340
341   <note>
342    <para>
343     If the <replaceable>expression</replaceable> is row-valued, then
344     <literal>IS NULL</> is true when the row expression itself is null
345     or when all the row's fields are null, while
346     <literal>IS NOT NULL</> is true when the row expression itself is non-null
347     and all the row's fields are non-null.
348     This definition conforms to the SQL standard, and is a change from the
349     inconsistent behavior exhibited by <productname>PostgreSQL</productname>
350     versions prior to 8.2.
351    </para>
352   </note>
353
354    <para>
355     <indexterm>
356      <primary>IS DISTINCT FROM</primary>
357     </indexterm>
358     <indexterm>
359      <primary>IS NOT DISTINCT FROM</primary>
360     </indexterm>
361     The ordinary comparison operators yield null (signifying <quote>unknown</>)
362     when either input is null.  Another way to do comparisons is with the
363     <literal>IS <optional> NOT </> DISTINCT FROM</literal> construct:
364 <synopsis>
365 <replaceable>expression</replaceable> IS DISTINCT FROM <replaceable>expression</replaceable>
366 <replaceable>expression</replaceable> IS NOT DISTINCT FROM <replaceable>expression</replaceable>
367 </synopsis>
368     For non-null inputs, <literal>IS DISTINCT FROM</literal> is
369     the same as the <literal>&lt;&gt;</> operator.  However, when both
370     inputs are null it will return false, and when just one input is
371     null it will return true.  Similarly, <literal>IS NOT DISTINCT
372     FROM</literal> is identical to <literal>=</literal> for non-null
373     inputs, but it returns true when both inputs are null, and false when only
374     one input is null. Thus, these constructs effectively act as though null
375     were a normal data value, rather than <quote>unknown</>.
376    </para>
377
378    <para>
379     <indexterm>
380      <primary>IS TRUE</primary>
381     </indexterm>
382     <indexterm>
383      <primary>IS NOT TRUE</primary>
384     </indexterm>
385     <indexterm>
386      <primary>IS FALSE</primary>
387     </indexterm>
388     <indexterm>
389      <primary>IS NOT FALSE</primary>
390     </indexterm>
391     <indexterm>
392      <primary>IS UNKNOWN</primary>
393     </indexterm>
394     <indexterm>
395      <primary>IS NOT UNKNOWN</primary>
396     </indexterm>
397     Boolean values can also be tested using the constructs
398 <synopsis>
399 <replaceable>expression</replaceable> IS TRUE
400 <replaceable>expression</replaceable> IS NOT TRUE
401 <replaceable>expression</replaceable> IS FALSE
402 <replaceable>expression</replaceable> IS NOT FALSE
403 <replaceable>expression</replaceable> IS UNKNOWN
404 <replaceable>expression</replaceable> IS NOT UNKNOWN
405 </synopsis>
406     These will always return true or false, never a null value, even when the
407     operand is null.
408     A null input is treated as the logical value <quote>unknown</>.
409     Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
410     effectively the same as <literal>IS NULL</literal> and
411     <literal>IS NOT NULL</literal>, respectively, except that the input
412     expression must be of Boolean type.
413    </para>
414  
415 <!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
416    <para>
417     <indexterm>
418      <primary>IS OF</primary>
419     </indexterm>
420     <indexterm>
421      <primary>IS NOT OF</primary>
422     </indexterm>
423     It is possible to check the data type of an expression using the
424     constructs
425 <synopsis>
426 <replaceable>expression</replaceable> IS OF (typename, ...)
427 <replaceable>expression</replaceable> IS NOT OF (typename, ...)
428 </synopsis>
429     They return a boolean value based on whether the expression's data
430     type is one of the listed data types.
431    </para>
432 -->
433
434   </sect1>
435
436   <sect1 id="functions-math">
437    <title>Mathematical Functions and Operators</title>
438
439    <para>
440     Mathematical operators are provided for many
441     <productname>PostgreSQL</productname> types. For types without
442     common mathematical conventions for all possible permutations 
443     (e.g., date/time types) we
444     describe the actual behavior in subsequent sections.
445    </para>
446
447    <para>
448     <xref linkend="functions-math-op-table"> shows the available mathematical operators.
449    </para>
450
451    <table id="functions-math-op-table">
452     <title>Mathematical Operators</title>
453
454     <tgroup cols="4">
455      <thead>
456       <row>
457        <entry>Operator</entry>
458        <entry>Description</entry>
459        <entry>Example</entry>
460        <entry>Result</entry>
461       </row>
462      </thead>
463
464      <tbody>
465       <row>
466        <entry> <literal>+</literal> </entry>
467        <entry>addition</entry>
468        <entry><literal>2 + 3</literal></entry>
469        <entry><literal>5</literal></entry>
470       </row>
471
472       <row>
473        <entry> <literal>-</literal> </entry>
474        <entry>subtraction</entry>
475        <entry><literal>2 - 3</literal></entry>
476        <entry><literal>-1</literal></entry>
477       </row>
478
479       <row>
480        <entry> <literal>*</literal> </entry>
481        <entry>multiplication</entry>
482        <entry><literal>2 * 3</literal></entry>
483        <entry><literal>6</literal></entry>
484       </row>
485
486       <row>
487        <entry> <literal>/</literal> </entry>
488        <entry>division (integer division truncates results)</entry>
489        <entry><literal>4 / 2</literal></entry>
490        <entry><literal>2</literal></entry>
491       </row>
492
493       <row>
494        <entry> <literal>%</literal> </entry>
495        <entry>modulo (remainder)</entry>
496        <entry><literal>5 % 4</literal></entry>
497        <entry><literal>1</literal></entry>
498       </row>
499
500       <row>
501        <entry> <literal>^</literal> </entry>
502        <entry>exponentiation</entry>
503        <entry><literal>2.0 ^ 3.0</literal></entry>
504        <entry><literal>8</literal></entry>
505       </row>
506
507       <row>
508        <entry> <literal>|/</literal> </entry>
509        <entry>square root</entry>
510        <entry><literal>|/ 25.0</literal></entry>
511        <entry><literal>5</literal></entry>
512       </row>
513
514       <row>
515        <entry> <literal>||/</literal> </entry>
516        <entry>cube root</entry>
517        <entry><literal>||/ 27.0</literal></entry>
518        <entry><literal>3</literal></entry>
519       </row>
520
521       <row>
522        <entry> <literal>!</literal> </entry>
523        <entry>factorial</entry>
524        <entry><literal>5 !</literal></entry>
525        <entry><literal>120</literal></entry>
526       </row>
527
528       <row>
529        <entry> <literal>!!</literal> </entry>
530        <entry>factorial (prefix operator)</entry>
531        <entry><literal>!! 5</literal></entry>
532        <entry><literal>120</literal></entry>
533       </row>
534
535       <row>
536        <entry> <literal>@</literal> </entry>
537        <entry>absolute value</entry>
538        <entry><literal>@ -5.0</literal></entry>
539        <entry><literal>5</literal></entry>
540       </row>
541
542       <row>
543        <entry> <literal>&amp;</literal> </entry>
544        <entry>bitwise AND</entry>
545        <entry><literal>91 &amp; 15</literal></entry>
546        <entry><literal>11</literal></entry>
547       </row>
548
549       <row>
550        <entry> <literal>|</literal> </entry>
551        <entry>bitwise OR</entry>
552        <entry><literal>32 | 3</literal></entry>
553        <entry><literal>35</literal></entry>
554       </row>
555
556       <row>
557        <entry> <literal>#</literal> </entry>
558        <entry>bitwise XOR</entry>
559        <entry><literal>17 # 5</literal></entry>
560        <entry><literal>20</literal></entry>
561       </row>
562
563       <row>
564        <entry> <literal>~</literal> </entry>
565        <entry>bitwise NOT</entry>
566        <entry><literal>~1</literal></entry>
567        <entry><literal>-2</literal></entry>
568       </row>
569
570       <row>
571        <entry> <literal>&lt;&lt;</literal> </entry>
572        <entry>bitwise shift left</entry>
573        <entry><literal>1 &lt;&lt; 4</literal></entry>
574        <entry><literal>16</literal></entry>
575       </row>
576
577       <row>
578        <entry> <literal>&gt;&gt;</literal> </entry>
579        <entry>bitwise shift right</entry>
580        <entry><literal>8 &gt;&gt; 2</literal></entry>
581        <entry><literal>2</literal></entry>
582       </row>
583
584      </tbody>
585     </tgroup>
586    </table>
587
588    <para>
589     The bitwise operators work only on integral data types, whereas
590     the others are available for all numeric data types.  The bitwise
591     operators are also available for the bit
592     string types <type>bit</type> and <type>bit varying</type>, as
593     shown in <xref linkend="functions-bit-string-op-table">.
594    </para>
595
596   <para>
597    <xref linkend="functions-math-func-table"> shows the available
598    mathematical functions.  In the table, <literal>dp</literal>
599    indicates <type>double precision</type>.  Many of these functions
600    are provided in multiple forms with different argument types.
601    Except where noted, any given form of a function returns the same
602    data type as its argument.
603    The functions working with <type>double precision</type> data are mostly
604    implemented on top of the host system's C library; accuracy and behavior in
605    boundary cases can therefore vary depending on the host system.
606   </para>
607
608    <indexterm>
609     <primary>abs</primary>
610    </indexterm>
611    <indexterm>
612     <primary>cbrt</primary>
613    </indexterm>
614    <indexterm>
615     <primary>ceiling</primary>
616    </indexterm>
617    <indexterm>
618     <primary>degrees</primary>
619    </indexterm>
620    <indexterm>
621     <primary>exp</primary>
622    </indexterm>
623    <indexterm>
624     <primary>floor</primary>
625    </indexterm>
626    <indexterm>
627     <primary>ln</primary>
628    </indexterm>
629    <indexterm>
630     <primary>log</primary>
631    </indexterm>
632    <indexterm>
633     <primary>mod</primary>
634    </indexterm>
635    <indexterm>
636     <primary>pi</primary>
637    </indexterm>
638    <indexterm>
639     <primary>power</primary>
640    </indexterm>
641    <indexterm>
642     <primary>radians</primary>
643    </indexterm>
644    <indexterm>
645     <primary>random</primary>
646    </indexterm>
647    <indexterm>
648     <primary>round</primary>
649    </indexterm>
650    <indexterm>
651     <primary>setseed</primary>
652    </indexterm>
653    <indexterm>
654     <primary>sign</primary>
655    </indexterm>
656    <indexterm>
657     <primary>sqrt</primary>
658    </indexterm>
659    <indexterm>
660     <primary>trunc</primary>
661    </indexterm>
662    <indexterm>
663     <primary>width_bucket</primary>
664    </indexterm>
665
666    <table id="functions-math-func-table">
667     <title>Mathematical Functions</title>
668     <tgroup cols="5">
669      <thead>
670       <row>
671        <entry>Function</entry>
672        <entry>Return Type</entry>
673        <entry>Description</entry>
674        <entry>Example</entry>
675        <entry>Result</entry>
676       </row>
677      </thead>
678
679      <tbody>
680       <row>
681        <entry><literal><function>abs</>(<replaceable>x</replaceable>)</literal></entry>
682        <entry>(same as <replaceable>x</>)</entry>
683        <entry>absolute value</entry>
684        <entry><literal>abs(-17.4)</literal></entry>
685        <entry><literal>17.4</literal></entry>
686       </row>
687
688       <row>
689        <entry><literal><function>cbrt</function>(<type>dp</type>)</literal></entry>
690        <entry><type>dp</type></entry>
691        <entry>cube root</entry>
692        <entry><literal>cbrt(27.0)</literal></entry>
693        <entry><literal>3</literal></entry>
694       </row>
695
696       <row>
697        <entry><literal><function>ceil</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
698        <entry>(same as input)</entry>
699        <entry>smallest integer not less than argument</entry>
700        <entry><literal>ceil(-42.8)</literal></entry>
701        <entry><literal>-42</literal></entry>
702       </row>
703
704       <row>
705        <entry><literal><function>ceiling</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
706        <entry>(same as input)</entry>
707        <entry>smallest integer not less than argument (alias for <function>ceil</function>)</entry>
708        <entry><literal>ceiling(-95.3)</literal></entry>
709        <entry><literal>-95</literal></entry>
710       </row>
711
712       <row>
713        <entry><literal><function>degrees</function>(<type>dp</type>)</literal></entry>
714        <entry><type>dp</type></entry>
715        <entry>radians to degrees</entry>
716        <entry><literal>degrees(0.5)</literal></entry>
717        <entry><literal>28.6478897565412</literal></entry>
718       </row>
719
720       <row>
721        <entry><literal><function>exp</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
722        <entry>(same as input)</entry>
723        <entry>exponential</entry>
724        <entry><literal>exp(1.0)</literal></entry>
725        <entry><literal>2.71828182845905</literal></entry>
726       </row>
727
728       <row>
729        <entry><literal><function>floor</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
730        <entry>(same as input)</entry>
731        <entry>largest integer not greater than argument</entry>
732        <entry><literal>floor(-42.8)</literal></entry>
733        <entry><literal>-43</literal></entry>
734       </row>
735
736       <row>
737        <entry><literal><function>ln</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
738        <entry>(same as input)</entry>
739        <entry>natural logarithm</entry>
740        <entry><literal>ln(2.0)</literal></entry>
741        <entry><literal>0.693147180559945</literal></entry>
742       </row>
743
744       <row>
745        <entry><literal><function>log</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
746        <entry>(same as input)</entry>
747        <entry>base 10 logarithm</entry>
748        <entry><literal>log(100.0)</literal></entry>
749        <entry><literal>2</literal></entry>
750       </row>
751
752       <row>
753        <entry><literal><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
754         <parameter>x</parameter> <type>numeric</type>)</literal></entry>
755        <entry><type>numeric</type></entry>
756        <entry>logarithm to base <parameter>b</parameter></entry>
757        <entry><literal>log(2.0, 64.0)</literal></entry>
758        <entry><literal>6.0000000000</literal></entry>
759       </row>
760
761       <row>
762        <entry><literal><function>mod</function>(<parameter>y</parameter>,
763         <parameter>x</parameter>)</literal></entry>
764        <entry>(same as argument types)</entry>
765        <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
766        <entry><literal>mod(9,4)</literal></entry>
767        <entry><literal>1</literal></entry>
768       </row>
769
770       <row>
771        <entry><literal><function>pi</function>()</literal></entry>
772        <entry><type>dp</type></entry>
773        <entry><quote>&pi;</quote> constant</entry>
774        <entry><literal>pi()</literal></entry>
775        <entry><literal>3.14159265358979</literal></entry>
776       </row>
777
778       <row>
779        <entry><literal><function>power</function>(<parameter>a</parameter> <type>dp</type>,
780         <parameter>b</parameter> <type>dp</type>)</literal></entry>
781        <entry><type>dp</type></entry>
782        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
783        <entry><literal>power(9.0, 3.0)</literal></entry>
784        <entry><literal>729</literal></entry>
785       </row>
786
787       <row>
788        <entry><literal><function>power</function>(<parameter>a</parameter> <type>numeric</type>,
789         <parameter>b</parameter> <type>numeric</type>)</literal></entry>
790        <entry><type>numeric</type></entry>
791        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
792        <entry><literal>power(9.0, 3.0)</literal></entry>
793        <entry><literal>729</literal></entry>
794       </row>
795
796       <row>
797        <entry><literal><function>radians</function>(<type>dp</type>)</literal></entry>
798        <entry><type>dp</type></entry>
799        <entry>degrees to radians</entry>
800        <entry><literal>radians(45.0)</literal></entry>
801        <entry><literal>0.785398163397448</literal></entry>
802       </row>
803
804       <row>
805        <entry><literal><function>random</function>()</literal></entry>
806        <entry><type>dp</type></entry>
807        <entry>random value between 0.0 and 1.0</entry>
808        <entry><literal>random()</literal></entry>
809        <entry></entry>
810       </row>
811
812       <row>
813        <entry><literal><function>round</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
814        <entry>(same as input)</entry>
815        <entry>round to nearest integer</entry>
816        <entry><literal>round(42.4)</literal></entry>
817        <entry><literal>42</literal></entry>
818       </row>
819
820       <row>
821        <entry><literal><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
822        <entry><type>numeric</type></entry>
823        <entry>round to <parameter>s</parameter> decimal places</entry>
824        <entry><literal>round(42.4382, 2)</literal></entry>
825        <entry><literal>42.44</literal></entry>
826       </row>
827
828       <row>
829        <entry><literal><function>setseed</function>(<type>dp</type>)</literal></entry>
830        <entry><type>void</type></entry>
831        <entry>set seed for subsequent <literal>random()</literal> calls (value between 0 and 1.0)</entry>
832        <entry><literal>setseed(0.54823)</literal></entry>
833        <entry></entry>
834       </row>
835
836       <row>
837        <entry><literal><function>sign</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
838        <entry>(same as input)</entry>
839        <entry>sign of the argument (-1, 0, +1)</entry>
840        <entry><literal>sign(-8.4)</literal></entry>
841        <entry><literal>-1</literal></entry>
842       </row>
843
844       <row>
845        <entry><literal><function>sqrt</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
846        <entry>(same as input)</entry>
847        <entry>square root</entry>
848        <entry><literal>sqrt(2.0)</literal></entry>
849        <entry><literal>1.4142135623731</literal></entry>
850       </row>
851
852       <row>
853        <entry><literal><function>trunc</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
854        <entry>(same as input)</entry>
855        <entry>truncate toward zero</entry>
856        <entry><literal>trunc(42.8)</literal></entry>
857        <entry><literal>42</literal></entry>
858       </row>
859
860       <row>
861        <entry><literal><function>trunc</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
862        <entry><type>numeric</type></entry>
863        <entry>truncate to <parameter>s</parameter> decimal places</entry>
864        <entry><literal>trunc(42.4382, 2)</literal></entry>
865        <entry><literal>42.43</literal></entry>
866       </row>
867
868       <row>
869        <entry><literal><function>width_bucket</function>(<parameter>op</parameter> <type>numeric</type>, <parameter>b1</parameter> <type>numeric</type>, <parameter>b2</parameter> <type>numeric</type>, <parameter>count</parameter> <type>int</type>)</literal></entry>
870        <entry><type>int</type></entry>
871        <entry>return the bucket to which <parameter>operand</> would
872        be assigned in an equidepth histogram with <parameter>count</>
873        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
874        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
875        <entry><literal>3</literal></entry>
876       </row>
877
878       <row>
879        <entry><literal><function>width_bucket</function>(<parameter>op</parameter> <type>dp</type>, <parameter>b1</parameter> <type>dp</type>, <parameter>b2</parameter> <type>dp</type>, <parameter>count</parameter> <type>int</type>)</literal></entry>
880        <entry><type>int</type></entry>
881        <entry>return the bucket to which <parameter>operand</> would
882        be assigned in an equidepth histogram with <parameter>count</>
883        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
884        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
885        <entry><literal>3</literal></entry>
886       </row>
887      </tbody>
888     </tgroup>
889    </table>
890
891   <para>
892    Finally, <xref linkend="functions-math-trig-table"> shows the
893    available trigonometric functions.  All trigonometric functions
894    take arguments and return values of type <type>double
895    precision</type>.
896   </para>
897
898    <indexterm>
899     <primary>acos</primary>
900    </indexterm>
901    <indexterm>
902     <primary>asin</primary>
903    </indexterm>
904    <indexterm>
905     <primary>atan</primary>
906    </indexterm>
907    <indexterm>
908     <primary>atan2</primary>
909    </indexterm>
910    <indexterm>
911     <primary>cos</primary>
912    </indexterm>
913    <indexterm>
914     <primary>cot</primary>
915    </indexterm>
916    <indexterm>
917     <primary>sin</primary>
918    </indexterm>
919    <indexterm>
920     <primary>tan</primary>
921    </indexterm>
922
923    <table id="functions-math-trig-table">
924     <title>Trigonometric Functions</title>
925
926     <tgroup cols="2">
927      <thead>
928       <row>
929        <entry>Function</entry>
930        <entry>Description</entry>
931       </row>
932      </thead>
933
934      <tbody>
935       <row>
936        <entry><literal><function>acos</function>(<replaceable>x</replaceable>)</literal></entry>
937        <entry>inverse cosine</entry>
938       </row>
939
940       <row>
941        <entry><literal><function>asin</function>(<replaceable>x</replaceable>)</literal></entry>
942        <entry>inverse sine</entry>
943       </row>
944
945       <row>
946        <entry><literal><function>atan</function>(<replaceable>x</replaceable>)</literal></entry>
947        <entry>inverse tangent</entry>
948       </row>
949
950       <row>
951        <entry><literal><function>atan2</function>(<replaceable>y</replaceable>,
952         <replaceable>x</replaceable>)</literal></entry>
953        <entry>inverse tangent of
954         <literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
955       </row>
956
957       <row>
958        <entry><literal><function>cos</function>(<replaceable>x</replaceable>)</literal></entry>
959        <entry>cosine</entry>
960       </row>
961
962       <row>
963        <entry><literal><function>cot</function>(<replaceable>x</replaceable>)</literal></entry>
964        <entry>cotangent</entry>
965       </row>
966
967       <row>
968        <entry><literal><function>sin</function>(<replaceable>x</replaceable>)</literal></entry>
969        <entry>sine</entry>
970       </row>
971
972       <row>
973        <entry><literal><function>tan</function>(<replaceable>x</replaceable>)</literal></entry>
974        <entry>tangent</entry>
975       </row>
976      </tbody>
977     </tgroup>
978    </table>
979
980   </sect1>
981
982
983   <sect1 id="functions-string">
984    <title>String Functions and Operators</title>
985
986    <para>
987     This section describes functions and operators for examining and
988     manipulating string values.  Strings in this context include values
989     of the types <type>character</type>, <type>character varying</type>,
990     and <type>text</type>.  Unless otherwise noted, all
991     of the functions listed below work on all of these types, but be
992     wary of potential effects of automatic space-padding when using the
993     <type>character</type> type.  Some functions also exist
994     natively for the bit-string types.
995    </para>
996
997    <para>
998     <acronym>SQL</acronym> defines some string functions with a special syntax
999     wherein certain key words rather than commas are used to separate the
1000     arguments.  Details are in <xref linkend="functions-string-sql">.
1001     These functions are also implemented using the regular syntax for
1002     function invocation.  (See <xref linkend="functions-string-other">.)
1003    </para>
1004
1005    <note>
1006     <para>
1007      Before <productname>PostgreSQL</productname> 8.3, these functions would
1008      silently accept values of several non-string data types as well, due to
1009      the presence of implicit coercions from those data types to
1010      <type>text</>.  Those coercions have been removed because they frequently
1011      caused surprising behaviors.  However, the string concatenation operator
1012      (<literal>||</>) still accepts non-string input, so long as at least one
1013      input is of a string type, as shown in <xref
1014      linkend="functions-string-sql">.  For other cases, insert an explicit
1015      coercion to <type>text</> if you need to duplicate the previous behavior.
1016     </para>
1017    </note>
1018
1019    <indexterm>
1020     <primary>bit_length</primary>
1021    </indexterm>
1022    <indexterm>
1023     <primary>char_length</primary>
1024    </indexterm>
1025    <indexterm>
1026     <primary>lower</primary>
1027    </indexterm>
1028    <indexterm>
1029     <primary>octet_length</primary>
1030    </indexterm>
1031    <indexterm>
1032     <primary>overlay</primary>
1033    </indexterm>
1034    <indexterm>
1035     <primary>position</primary>
1036    </indexterm>
1037    <indexterm>
1038     <primary>substring</primary>
1039    </indexterm>
1040    <indexterm>
1041     <primary>trim</primary>
1042    </indexterm>
1043    <indexterm>
1044     <primary>upper</primary>
1045    </indexterm>
1046
1047    <table id="functions-string-sql">
1048     <title><acronym>SQL</acronym> String Functions and Operators</title>
1049     <tgroup cols="5">
1050      <thead>
1051       <row>
1052        <entry>Function</entry>
1053        <entry>Return Type</entry>
1054        <entry>Description</entry>
1055        <entry>Example</entry>
1056        <entry>Result</entry>  
1057       </row>
1058      </thead>
1059
1060      <tbody>
1061       <row>
1062        <entry><literal><parameter>string</parameter> <literal>||</literal>
1063         <parameter>string</parameter></literal></entry>
1064        <entry> <type>text</type> </entry>
1065        <entry>
1066         String concatenation
1067         <indexterm>
1068          <primary>character string</primary>
1069          <secondary>concatenation</secondary>
1070         </indexterm>
1071        </entry>
1072        <entry><literal>'Post' || 'greSQL'</literal></entry>
1073        <entry><literal>PostgreSQL</literal></entry>
1074       </row>
1075
1076       <row>
1077        <entry>
1078         <literal><parameter>string</parameter> <literal>||</literal>
1079         <parameter>non-string</parameter></literal>
1080         or
1081         <literal><parameter>non-string</parameter> <literal>||</literal>
1082         <parameter>string</parameter></literal>
1083        </entry>
1084        <entry> <type>text</type> </entry>
1085        <entry>
1086         String concatenation with one non-string input
1087        </entry>
1088        <entry><literal>'Value: ' || 42</literal></entry>
1089        <entry><literal>Value: 42</literal></entry>
1090       </row>
1091
1092       <row>
1093        <entry><literal><function>bit_length</function>(<parameter>string</parameter>)</literal></entry>
1094        <entry><type>int</type></entry>
1095        <entry>Number of bits in string</entry>
1096        <entry><literal>bit_length('jose')</literal></entry>
1097        <entry><literal>32</literal></entry>
1098       </row>
1099
1100       <row>
1101        <entry><literal><function>char_length</function>(<parameter>string</parameter>)</literal> or <literal><function>character_length</function>(<parameter>string</parameter>)</literal></entry>
1102        <entry><type>int</type></entry>
1103        <entry>
1104         Number of characters in string
1105         <indexterm>
1106          <primary>character string</primary>
1107          <secondary>length</secondary>
1108         </indexterm>
1109         <indexterm>
1110          <primary>length</primary>
1111          <secondary sortas="character string">of a character string</secondary>
1112          <see>character string, length</see>
1113         </indexterm>
1114        </entry>
1115        <entry><literal>char_length('jose')</literal></entry>
1116        <entry><literal>4</literal></entry>
1117       </row>
1118
1119       <row>
1120        <entry><literal><function>lower</function>(<parameter>string</parameter>)</literal></entry>
1121        <entry><type>text</type></entry>
1122        <entry>Convert string to lower case</entry>
1123        <entry><literal>lower('TOM')</literal></entry>
1124        <entry><literal>tom</literal></entry>
1125       </row>
1126
1127       <row>
1128        <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
1129        <entry><type>int</type></entry>
1130        <entry>Number of bytes in string</entry>
1131        <entry><literal>octet_length('jose')</literal></entry>
1132        <entry><literal>4</literal></entry>
1133       </row>
1134
1135       <row>
1136        <entry><literal><function>overlay</function>(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</literal></entry>
1137        <entry><type>text</type></entry>
1138        <entry>
1139         Replace substring
1140        </entry>
1141        <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
1142        <entry><literal>Thomas</literal></entry>
1143       </row>
1144
1145       <row>
1146        <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
1147        <entry><type>int</type></entry>
1148        <entry>Location of specified substring</entry>
1149        <entry><literal>position('om' in 'Thomas')</literal></entry>
1150        <entry><literal>3</literal></entry>
1151       </row>
1152
1153       <row>
1154        <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
1155        <entry><type>text</type></entry>
1156        <entry>
1157         Extract substring
1158        </entry>
1159        <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
1160        <entry><literal>hom</literal></entry>
1161       </row>
1162
1163       <row>
1164        <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</literal></entry>
1165        <entry><type>text</type></entry>
1166        <entry>
1167         Extract substring matching POSIX regular expression. See
1168         <xref linkend="functions-matching"> for more information on pattern
1169         matching.
1170        </entry>
1171        <entry><literal>substring('Thomas' from '...$')</literal></entry>
1172        <entry><literal>mas</literal></entry>
1173       </row>
1174
1175       <row>
1176        <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</literal></entry>
1177        <entry><type>text</type></entry>
1178        <entry>
1179         Extract substring matching <acronym>SQL</acronym> regular expression.
1180         See <xref linkend="functions-matching"> for more information on
1181         pattern matching.
1182        </entry>
1183        <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
1184        <entry><literal>oma</literal></entry>
1185       </row>
1186
1187       <row>
1188        <entry>
1189         <literal><function>trim</function>(<optional>leading | trailing | both</optional>
1190         <optional><parameter>characters</parameter></optional> from
1191         <parameter>string</parameter>)</literal>
1192        </entry>
1193        <entry><type>text</type></entry>
1194        <entry>
1195         Remove the longest string containing only the
1196         <parameter>characters</parameter> (a space by default) from the
1197         start/end/both ends of the <parameter>string</parameter>
1198        </entry>
1199        <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
1200        <entry><literal>Tom</literal></entry>
1201       </row>
1202
1203       <row>
1204        <entry><literal><function>upper</function>(<parameter>string</parameter>)</literal></entry>
1205        <entry><type>text</type></entry>
1206        <entry>Convert string to uppercase</entry>
1207        <entry><literal>upper('tom')</literal></entry>
1208        <entry><literal>TOM</literal></entry>
1209       </row>
1210      </tbody>
1211     </tgroup>
1212    </table>
1213
1214    <para>
1215     Additional string manipulation functions are available and are
1216     listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
1217     <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
1218    </para>
1219
1220    <indexterm>
1221     <primary>ascii</primary>
1222    </indexterm>
1223    <indexterm>
1224     <primary>btrim</primary>
1225    </indexterm>
1226    <indexterm>
1227     <primary>chr</primary>
1228    </indexterm>
1229    <indexterm>
1230     <primary>convert</primary>
1231    </indexterm>
1232    <indexterm>
1233     <primary>convert_from</primary>
1234    </indexterm>
1235    <indexterm>
1236     <primary>convert_to</primary>
1237    </indexterm>
1238    <indexterm>
1239     <primary>decode</primary>
1240    </indexterm>
1241    <indexterm>
1242     <primary>encode</primary>
1243    </indexterm>
1244    <indexterm>
1245     <primary>initcap</primary>
1246    </indexterm>
1247    <indexterm>
1248     <primary>lpad</primary>
1249    </indexterm>
1250    <indexterm>
1251     <primary>ltrim</primary>
1252    </indexterm>
1253    <indexterm>
1254     <primary>md5</primary>
1255    </indexterm>
1256    <indexterm>
1257     <primary>pg_client_encoding</primary>
1258    </indexterm>
1259    <indexterm>
1260     <primary>quote_ident</primary>
1261    </indexterm>
1262    <indexterm>
1263     <primary>quote_literal</primary>
1264    </indexterm>
1265    <indexterm>
1266     <primary>repeat</primary>
1267    </indexterm>
1268    <indexterm>
1269     <primary>replace</primary>
1270    </indexterm>
1271    <indexterm>
1272     <primary>rpad</primary>
1273    </indexterm>
1274    <indexterm>
1275     <primary>rtrim</primary>
1276    </indexterm>
1277    <indexterm>
1278     <primary>split_part</primary>
1279    </indexterm>
1280    <indexterm>
1281     <primary>strpos</primary>
1282    </indexterm>
1283    <indexterm>
1284     <primary>substr</primary>
1285    </indexterm>
1286    <indexterm>
1287     <primary>to_ascii</primary>
1288    </indexterm>
1289    <indexterm>
1290     <primary>to_hex</primary>
1291    </indexterm>
1292    <indexterm>
1293     <primary>translate</primary>
1294    </indexterm>
1295
1296    <table id="functions-string-other">
1297     <title>Other String Functions</title>
1298     <tgroup cols="5">
1299      <thead>
1300       <row>
1301        <entry>Function</entry>
1302        <entry>Return Type</entry>
1303        <entry>Description</entry>
1304        <entry>Example</entry>
1305        <entry>Result</entry>
1306       </row>
1307      </thead>
1308
1309      <tbody>
1310       <row>
1311        <entry><literal><function>ascii</function>(<parameter>string</parameter>)</literal></entry>
1312        <entry><type>int</type></entry>
1313        <entry>
1314         <acronym>ASCII</acronym> code of the first character of the
1315         argument.  For <acronym>UTF8</acronym> returns the Unicode code
1316         point of the character.  For other multibyte encodings. the
1317         argument must be a strictly <acronym>ASCII</acronym> character.
1318        </entry>
1319        <entry><literal>ascii('x')</literal></entry>
1320        <entry><literal>120</literal></entry>
1321       </row>
1322
1323       <row>
1324        <entry><literal><function>btrim</function>(<parameter>string</parameter> <type>text</type>
1325        <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal></entry>
1326        <entry><type>text</type></entry>
1327        <entry>
1328         Remove the longest string consisting only of characters
1329         in <parameter>characters</parameter> (a space by default)
1330         from the start and end of <parameter>string</parameter>
1331        </entry>
1332        <entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
1333        <entry><literal>trim</literal></entry>
1334       </row>
1335
1336       <row>
1337        <entry><literal><function>chr</function>(<type>int</type>)</literal></entry>
1338        <entry><type>text</type></entry>
1339        <entry>
1340         Character with the given code. For <acronym>UTF8</acronym> the
1341         argument is treated as a Unicode code point. For other multibyte
1342         encodings the argument must designate a strictly
1343         <acronym>ASCII</acronym> character.  The NULL (0) character is not
1344         allowed because text data types cannot reliably store such bytes.
1345        </entry>
1346        <entry><literal>chr(65)</literal></entry>
1347        <entry><literal>A</literal></entry>
1348       </row>
1349
1350       <row>
1351        <entry>
1352         <literal><function>convert</function>(<parameter>string</parameter> <type>bytea</type>,
1353         <parameter>src_encoding</parameter> <type>name</type>,
1354         <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1355        </entry>
1356        <entry><type>bytea</type></entry>
1357        <entry>
1358         Convert string to <parameter>dest_encoding</parameter>.  The
1359         original encoding is specified by
1360         <parameter>src_encoding</parameter>. The
1361         <parameter>string</parameter> must be valid in this encoding.
1362         Conversions can be defined by <command>CREATE CONVERSION</command>.  
1363         Also there are some predefined conversions. See <xref
1364         linkend="conversion-names"> for available conversions.
1365        </entry>
1366        <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1367        <entry><literal>text_in_utf8</literal> represented in ISO 8859-1 encoding</entry>
1368       </row>
1369
1370       <row>
1371        <entry>
1372         <literal><function>convert_from</function>(<parameter>string</parameter> <type>bytea</type>,
1373         <parameter>src_encoding</parameter> <type>name</type>)</literal>
1374        </entry>
1375        <entry><type>text</type></entry>
1376        <entry>
1377         Convert string to the database encoding.  The original encoding
1378         is specified by <parameter>src_encoding</parameter>. The
1379         <parameter>string</parameter> must be valid in this encoding.
1380        </entry>
1381        <entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
1382        <entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
1383       </row>
1384
1385       <row>
1386        <entry>
1387         <literal><function>convert_to</function>(<parameter>string</parameter> <type>text</type>,
1388         <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1389        </entry>
1390        <entry><type>bytea</type></entry>
1391        <entry>
1392         Convert string to <parameter>dest_encoding</parameter>.
1393        </entry>
1394        <entry><literal>convert_to('some text', 'UTF8')</literal></entry>
1395        <entry><literal>some text</literal> represented in the UTF8 encoding</entry>
1396       </row>
1397
1398       <row>
1399        <entry>
1400         <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
1401         <parameter>type</parameter> <type>text</type>)</literal>
1402        </entry>
1403        <entry><type>bytea</type></entry>
1404        <entry>
1405         Decode binary data from <parameter>string</parameter> previously 
1406         encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
1407        </entry>
1408        <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
1409        <entry><literal>123\000\001</literal></entry>
1410       </row>       
1411
1412       <row>
1413        <entry>
1414         <literal><function>encode</function>(<parameter>data</parameter> <type>bytea</type>,
1415         <parameter>type</parameter> <type>text</type>)</literal>
1416        </entry>
1417        <entry><type>text</type></entry>
1418        <entry>
1419         Encode binary data to different representation.  Supported
1420         types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
1421         <literal>Escape</> merely outputs null bytes as <literal>\000</> and
1422         doubles backslashes.
1423        </entry>
1424        <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1425        <entry><literal>MTIzAAE=</literal></entry>
1426       </row>       
1427
1428       <row>
1429        <entry><literal><function>initcap</function>(<parameter>string</parameter>)</literal></entry>
1430        <entry><type>text</type></entry>
1431        <entry>
1432         Convert the first letter of each word to uppercase and the
1433         rest to lowercase. Words are sequences of alphanumeric
1434         characters separated by non-alphanumeric characters.
1435        </entry>
1436        <entry><literal>initcap('hi THOMAS')</literal></entry>
1437        <entry><literal>Hi Thomas</literal></entry>
1438       </row>
1439
1440       <row>
1441        <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
1442        <entry><type>int</type></entry>
1443        <entry>
1444         Number of characters in <parameter>string</parameter>
1445        </entry>
1446        <entry><literal>length('jose')</literal></entry>
1447        <entry><literal>4</literal></entry>
1448       </row>
1449
1450       <row>
1451        <entry><literal><function>length</function>(<parameter>string</parameter><type>bytea</type>,
1452         <parameter>encoding</parameter> <type>name</type> )</literal></entry>
1453        <entry><type>int</type></entry>
1454        <entry>
1455         Number of characters in <parameter>string</parameter> in the given
1456         <parameter>encoding</parameter>. The <parameter>string</parameter>
1457         must be valid in this encoding.
1458        </entry>
1459        <entry><literal>length('jose', 'UTF8')</literal></entry>
1460        <entry><literal>4</literal></entry>
1461       </row>
1462
1463       <row>
1464        <entry>
1465         <literal><function>lpad</function>(<parameter>string</parameter> <type>text</type>,
1466         <parameter>length</parameter> <type>int</type>
1467         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1468        </entry>
1469        <entry><type>text</type></entry>
1470        <entry>
1471         Fill up the <parameter>string</parameter> to length
1472         <parameter>length</parameter> by prepending the characters
1473         <parameter>fill</parameter> (a space by default).  If the
1474         <parameter>string</parameter> is already longer than
1475         <parameter>length</parameter> then it is truncated (on the
1476         right).
1477        </entry>
1478        <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1479        <entry><literal>xyxhi</literal></entry>
1480       </row>
1481
1482       <row>
1483        <entry><literal><function>ltrim</function>(<parameter>string</parameter> <type>text</type>
1484         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
1485        </entry>
1486        <entry><type>text</type></entry>
1487        <entry>
1488         Remove the longest string containing only characters from
1489         <parameter>characters</parameter> (a space by default) from the start of
1490         <parameter>string</parameter>
1491        </entry>
1492        <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
1493        <entry><literal>trim</literal></entry>
1494       </row>
1495
1496       <row>
1497        <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
1498        <entry><type>text</type></entry>
1499        <entry>
1500         Calculates the MD5 hash of <parameter>string</parameter>,
1501         returning the result in hexadecimal
1502        </entry>
1503        <entry><literal>md5('abc')</literal></entry>
1504        <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1505       </row>
1506
1507       <row>
1508        <entry><literal><function>pg_client_encoding</function>()</literal></entry>
1509        <entry><type>name</type></entry>
1510        <entry>
1511         Current client encoding name
1512        </entry>
1513        <entry><literal>pg_client_encoding()</literal></entry>
1514        <entry><literal>SQL_ASCII</literal></entry>
1515       </row>
1516
1517       <row>
1518        <entry><literal><function>quote_ident</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
1519        <entry><type>text</type></entry>
1520        <entry>
1521         Return the given string suitably quoted to be used as an identifier
1522         in an <acronym>SQL</acronym> statement string.
1523         Quotes are added only if necessary (i.e., if the string contains
1524         non-identifier characters or would be case-folded).
1525         Embedded quotes are properly doubled.
1526        </entry>
1527        <entry><literal>quote_ident('Foo bar')</literal></entry>
1528        <entry><literal>"Foo bar"</literal></entry>
1529       </row>
1530
1531       <row>
1532        <entry><literal><function>quote_literal</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
1533        <entry><type>text</type></entry>
1534        <entry>
1535         Return the given string suitably quoted to be used as a string literal
1536         in an <acronym>SQL</acronym> statement string.
1537         Embedded single-quotes and backslashes are properly doubled.
1538        </entry>
1539        <entry><literal>quote_literal('O\'Reilly')</literal></entry>
1540        <entry><literal>'O''Reilly'</literal></entry>
1541       </row>
1542
1543       <row>
1544        <entry><literal><function>quote_literal</function>(<parameter>value</parameter> <type>anyelement</type>)</literal></entry>
1545        <entry><type>text</type></entry>
1546        <entry>
1547         Coerce the given value to text and then quote it as a literal.
1548         Embedded single-quotes and backslashes are properly doubled.
1549        </entry>
1550        <entry><literal>quote_literal(42.5)</literal></entry>
1551        <entry><literal>'42.5'</literal></entry>
1552       </row>
1553
1554       <row>
1555        <entry><literal><function>regexp_matches</function>(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</literal></entry>
1556        <entry><type>setof text[]</type></entry>
1557        <entry>
1558         Return all captured substrings resulting from matching a POSIX regular
1559         expression against the <parameter>string</parameter>. See
1560         <xref linkend="functions-posix-regexp"> for more information.
1561        </entry>
1562        <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
1563        <entry><literal>{bar,beque}</literal></entry>
1564       </row>
1565
1566       <row>
1567        <entry><literal><function>regexp_replace</function>(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</literal></entry>
1568        <entry><type>text</type></entry>
1569        <entry>
1570         Replace substring(s) matching a POSIX regular expression. See
1571         <xref linkend="functions-posix-regexp"> for more information.
1572        </entry>
1573        <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
1574        <entry><literal>ThM</literal></entry>
1575       </row>
1576
1577       <row>
1578        <entry><literal><function>regexp_split_to_array</function>(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ])</literal></entry>
1579        <entry><type>text[]</type></entry>
1580        <entry>
1581         Split <parameter>string</parameter> using a POSIX regular expression as
1582         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1583         information.
1584        </entry>
1585        <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
1586        <entry><literal>{hello,world}</literal></entry>
1587       </row>
1588
1589       <row>
1590        <entry><literal><function>regexp_split_to_table</function>(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</literal></entry>
1591        <entry><type>setof text</type></entry>
1592        <entry>
1593         Split <parameter>string</parameter> using a POSIX regular expression as
1594         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1595         information.
1596        </entry>
1597        <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
1598        <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
1599       </row>
1600
1601       <row>
1602        <entry><literal><function>repeat</function>(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</literal></entry>
1603        <entry><type>text</type></entry>
1604        <entry>Repeat <parameter>string</parameter> the specified
1605        <parameter>number</parameter> of times</entry>
1606        <entry><literal>repeat('Pg', 4)</literal></entry>
1607        <entry><literal>PgPgPgPg</literal></entry>
1608       </row>
1609
1610       <row>
1611        <entry><literal><function>replace</function>(<parameter>string</parameter> <type>text</type>,
1612        <parameter>from</parameter> <type>text</type>,
1613        <parameter>to</parameter> <type>text</type>)</literal></entry>
1614        <entry><type>text</type></entry>
1615        <entry>Replace all occurrences in <parameter>string</parameter> of substring
1616         <parameter>from</parameter> with substring <parameter>to</parameter>
1617        </entry>
1618        <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
1619        <entry><literal>abXXefabXXef</literal></entry>
1620       </row>
1621
1622       <row>
1623        <entry>
1624         <literal><function>rpad</function>(<parameter>string</parameter> <type>text</type>,
1625         <parameter>length</parameter> <type>int</type>
1626         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1627        </entry>
1628        <entry><type>text</type></entry>
1629        <entry>
1630         Fill up the <parameter>string</parameter> to length
1631         <parameter>length</parameter> by appending the characters
1632         <parameter>fill</parameter> (a space by default).  If the
1633         <parameter>string</parameter> is already longer than
1634         <parameter>length</parameter> then it is truncated.
1635        </entry>
1636        <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
1637        <entry><literal>hixyx</literal></entry>
1638       </row>
1639
1640       <row>
1641        <entry><literal><function>rtrim</function>(<parameter>string</parameter> <type>text</type>
1642         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
1643        </entry>
1644        <entry><type>text</type></entry>
1645        <entry>
1646         Remove the longest string containing only characters from
1647         <parameter>characters</parameter> (a space by default) from the end of
1648         <parameter>string</parameter>
1649        </entry>
1650        <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
1651        <entry><literal>trim</literal></entry>
1652       </row>
1653
1654       <row>
1655        <entry><literal><function>split_part</function>(<parameter>string</parameter> <type>text</type>,
1656        <parameter>delimiter</parameter> <type>text</type>,
1657        <parameter>field</parameter> <type>int</type>)</literal></entry>
1658        <entry><type>text</type></entry>
1659        <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1660         and return the given field (counting from one)
1661        </entry>
1662        <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
1663        <entry><literal>def</literal></entry>
1664       </row>
1665
1666       <row>
1667        <entry><literal><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</literal></entry>
1668        <entry><type>int</type></entry>
1669        <entry>
1670         Location of specified substring (same as
1671         <literal>position(<parameter>substring</parameter> in
1672          <parameter>string</parameter>)</literal>, but note the reversed
1673         argument order)
1674        </entry>
1675        <entry><literal>strpos('high', 'ig')</literal></entry>
1676        <entry><literal>2</literal></entry>
1677       </row>
1678
1679       <row>
1680        <entry><literal><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</literal></entry>
1681        <entry><type>text</type></entry>
1682        <entry>
1683         Extract substring (same as
1684         <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
1685        </entry>
1686        <entry><literal>substr('alphabet', 3, 2)</literal></entry>
1687        <entry><literal>ph</literal></entry>
1688       </row>
1689
1690       <row>
1691        <entry><literal><function>to_ascii</function>(<parameter>string</parameter> <type>text</type>
1692         <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</literal></entry>
1693        <entry><type>text</type></entry>
1694
1695        <entry>
1696        Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
1697        (only supports conversion from  <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
1698        and <literal>WIN1250</> encodings)
1699        </entry>
1700
1701        <entry><literal>to_ascii('Karel')</literal></entry>
1702        <entry><literal>Karel</literal></entry>
1703       </row>
1704
1705       <row>
1706        <entry><literal><function>to_hex</function>(<parameter>number</parameter> <type>int</type>
1707        or <type>bigint</type>)</literal></entry>
1708        <entry><type>text</type></entry>
1709        <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
1710         representation
1711        </entry>
1712        <entry><literal>to_hex(2147483647)</literal></entry>
1713        <entry><literal>7fffffff</literal></entry>
1714       </row>
1715
1716       <row>
1717        <entry>
1718         <literal><function>translate</function>(<parameter>string</parameter> <type>text</type>,
1719         <parameter>from</parameter> <type>text</type>,
1720         <parameter>to</parameter> <type>text</type>)</literal>
1721        </entry>
1722        <entry><type>text</type></entry>
1723        <entry>
1724         Any character in <parameter>string</parameter> that matches a
1725         character in the <parameter>from</parameter> set is replaced by
1726         the corresponding character in the <parameter>to</parameter>
1727         set
1728        </entry>
1729        <entry><literal>translate('12345', '14', 'ax')</literal></entry>
1730        <entry><literal>a23x5</literal></entry>
1731       </row>       
1732       
1733      </tbody>
1734     </tgroup>
1735    </table>
1736
1737
1738    <table id="conversion-names">
1739     <title>Built-in Conversions</title>
1740     <tgroup cols="3">
1741      <thead>
1742       <row>
1743        <entry>Conversion Name
1744         <footnote>
1745          <para>
1746           The conversion names follow a standard naming scheme: The
1747           official name of the source encoding with all
1748           non-alphanumeric characters replaced by underscores followed
1749           by <literal>_to_</literal> followed by the equally processed
1750           destination encoding name. Therefore the names might deviate
1751           from the customary encoding names.
1752          </para>
1753         </footnote>
1754        </entry>
1755        <entry>Source Encoding</entry>
1756        <entry>Destination Encoding</entry>
1757       </row>
1758      </thead>
1759
1760      <tbody>
1761       <row>
1762        <entry><literal>ascii_to_mic</literal></entry>
1763        <entry><literal>SQL_ASCII</literal></entry>
1764        <entry><literal>MULE_INTERNAL</literal></entry>
1765       </row>
1766
1767       <row>
1768        <entry><literal>ascii_to_utf8</literal></entry>
1769        <entry><literal>SQL_ASCII</literal></entry>
1770        <entry><literal>UTF8</literal></entry>
1771       </row>
1772
1773       <row>
1774        <entry><literal>big5_to_euc_tw</literal></entry>
1775        <entry><literal>BIG5</literal></entry>
1776        <entry><literal>EUC_TW</literal></entry>
1777       </row>
1778
1779       <row>
1780        <entry><literal>big5_to_mic</literal></entry>
1781        <entry><literal>BIG5</literal></entry>
1782        <entry><literal>MULE_INTERNAL</literal></entry>
1783       </row>
1784
1785       <row>
1786        <entry><literal>big5_to_utf8</literal></entry>
1787        <entry><literal>BIG5</literal></entry>
1788        <entry><literal>UTF8</literal></entry>
1789       </row>
1790
1791       <row>
1792        <entry><literal>euc_cn_to_mic</literal></entry>
1793        <entry><literal>EUC_CN</literal></entry>
1794        <entry><literal>MULE_INTERNAL</literal></entry>
1795       </row>
1796
1797       <row>
1798        <entry><literal>euc_cn_to_utf8</literal></entry>
1799        <entry><literal>EUC_CN</literal></entry>
1800        <entry><literal>UTF8</literal></entry>
1801       </row>
1802
1803       <row>
1804        <entry><literal>euc_jp_to_mic</literal></entry>
1805        <entry><literal>EUC_JP</literal></entry>
1806        <entry><literal>MULE_INTERNAL</literal></entry>
1807       </row>
1808
1809       <row>
1810        <entry><literal>euc_jp_to_sjis</literal></entry>
1811        <entry><literal>EUC_JP</literal></entry>
1812        <entry><literal>SJIS</literal></entry>
1813       </row>
1814
1815       <row>
1816        <entry><literal>euc_jp_to_utf8</literal></entry>
1817        <entry><literal>EUC_JP</literal></entry>
1818        <entry><literal>UTF8</literal></entry>
1819       </row>
1820
1821       <row>
1822        <entry><literal>euc_kr_to_mic</literal></entry>
1823        <entry><literal>EUC_KR</literal></entry>
1824        <entry><literal>MULE_INTERNAL</literal></entry>
1825       </row>
1826
1827       <row>
1828        <entry><literal>euc_kr_to_utf8</literal></entry>
1829        <entry><literal>EUC_KR</literal></entry>
1830        <entry><literal>UTF8</literal></entry>
1831       </row>
1832
1833       <row>
1834        <entry><literal>euc_tw_to_big5</literal></entry>
1835        <entry><literal>EUC_TW</literal></entry>
1836        <entry><literal>BIG5</literal></entry>
1837       </row>
1838
1839       <row>
1840        <entry><literal>euc_tw_to_mic</literal></entry>
1841        <entry><literal>EUC_TW</literal></entry>
1842        <entry><literal>MULE_INTERNAL</literal></entry>
1843       </row>
1844
1845       <row>
1846        <entry><literal>euc_tw_to_utf8</literal></entry>
1847        <entry><literal>EUC_TW</literal></entry>
1848        <entry><literal>UTF8</literal></entry>
1849       </row>
1850
1851       <row>
1852        <entry><literal>gb18030_to_utf8</literal></entry>
1853        <entry><literal>GB18030</literal></entry>
1854        <entry><literal>UTF8</literal></entry>
1855       </row>
1856
1857       <row>
1858        <entry><literal>gbk_to_utf8</literal></entry>
1859        <entry><literal>GBK</literal></entry>
1860        <entry><literal>UTF8</literal></entry>
1861       </row>
1862
1863       <row>
1864        <entry><literal>iso_8859_10_to_utf8</literal></entry>
1865        <entry><literal>LATIN6</literal></entry>
1866        <entry><literal>UTF8</literal></entry>
1867       </row>
1868
1869       <row>
1870        <entry><literal>iso_8859_13_to_utf8</literal></entry>
1871        <entry><literal>LATIN7</literal></entry>
1872        <entry><literal>UTF8</literal></entry>
1873       </row>
1874
1875       <row>
1876        <entry><literal>iso_8859_14_to_utf8</literal></entry>
1877        <entry><literal>LATIN8</literal></entry>
1878        <entry><literal>UTF8</literal></entry>
1879       </row>
1880
1881       <row>
1882        <entry><literal>iso_8859_15_to_utf8</literal></entry>
1883        <entry><literal>LATIN9</literal></entry>
1884        <entry><literal>UTF8</literal></entry>
1885       </row>
1886
1887       <row>
1888        <entry><literal>iso_8859_16_to_utf8</literal></entry>
1889        <entry><literal>LATIN10</literal></entry>
1890        <entry><literal>UTF8</literal></entry>
1891       </row>
1892
1893       <row>
1894        <entry><literal>iso_8859_1_to_mic</literal></entry>
1895        <entry><literal>LATIN1</literal></entry>
1896        <entry><literal>MULE_INTERNAL</literal></entry>
1897       </row>
1898
1899       <row>
1900        <entry><literal>iso_8859_1_to_utf8</literal></entry>
1901        <entry><literal>LATIN1</literal></entry>
1902        <entry><literal>UTF8</literal></entry>
1903       </row>
1904
1905       <row>
1906        <entry><literal>iso_8859_2_to_mic</literal></entry>
1907        <entry><literal>LATIN2</literal></entry>
1908        <entry><literal>MULE_INTERNAL</literal></entry>
1909       </row>
1910
1911       <row>
1912        <entry><literal>iso_8859_2_to_utf8</literal></entry>
1913        <entry><literal>LATIN2</literal></entry>
1914        <entry><literal>UTF8</literal></entry>
1915       </row>
1916
1917       <row>
1918        <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
1919        <entry><literal>LATIN2</literal></entry>
1920        <entry><literal>WIN1250</literal></entry>
1921       </row>
1922
1923       <row>
1924        <entry><literal>iso_8859_3_to_mic</literal></entry>
1925        <entry><literal>LATIN3</literal></entry>
1926        <entry><literal>MULE_INTERNAL</literal></entry>
1927       </row>
1928
1929       <row>
1930        <entry><literal>iso_8859_3_to_utf8</literal></entry>
1931        <entry><literal>LATIN3</literal></entry>
1932        <entry><literal>UTF8</literal></entry>
1933       </row>
1934
1935       <row>
1936        <entry><literal>iso_8859_4_to_mic</literal></entry>
1937        <entry><literal>LATIN4</literal></entry>
1938        <entry><literal>MULE_INTERNAL</literal></entry>
1939       </row>
1940
1941       <row>
1942        <entry><literal>iso_8859_4_to_utf8</literal></entry>
1943        <entry><literal>LATIN4</literal></entry>
1944        <entry><literal>UTF8</literal></entry>
1945       </row>
1946
1947       <row>
1948        <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
1949        <entry><literal>ISO_8859_5</literal></entry>
1950        <entry><literal>KOI8</literal></entry>
1951       </row>
1952
1953       <row>
1954        <entry><literal>iso_8859_5_to_mic</literal></entry>
1955        <entry><literal>ISO_8859_5</literal></entry>
1956        <entry><literal>MULE_INTERNAL</literal></entry>
1957       </row>
1958
1959       <row>
1960        <entry><literal>iso_8859_5_to_utf8</literal></entry>
1961        <entry><literal>ISO_8859_5</literal></entry>
1962        <entry><literal>UTF8</literal></entry>
1963       </row>
1964
1965       <row>
1966        <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
1967        <entry><literal>ISO_8859_5</literal></entry>
1968        <entry><literal>WIN1251</literal></entry>
1969       </row>
1970
1971       <row>
1972        <entry><literal>iso_8859_5_to_windows_866</literal></entry>
1973        <entry><literal>ISO_8859_5</literal></entry>
1974        <entry><literal>WIN866</literal></entry>
1975       </row>
1976
1977       <row>
1978        <entry><literal>iso_8859_6_to_utf8</literal></entry>
1979        <entry><literal>ISO_8859_6</literal></entry>
1980        <entry><literal>UTF8</literal></entry>
1981       </row>
1982
1983       <row>
1984        <entry><literal>iso_8859_7_to_utf8</literal></entry>
1985        <entry><literal>ISO_8859_7</literal></entry>
1986        <entry><literal>UTF8</literal></entry>
1987       </row>
1988
1989       <row>
1990        <entry><literal>iso_8859_8_to_utf8</literal></entry>
1991        <entry><literal>ISO_8859_8</literal></entry>
1992        <entry><literal>UTF8</literal></entry>
1993       </row>
1994
1995       <row>
1996        <entry><literal>iso_8859_9_to_utf8</literal></entry>
1997        <entry><literal>LATIN5</literal></entry>
1998        <entry><literal>UTF8</literal></entry>
1999       </row>
2000
2001       <row>
2002        <entry><literal>johab_to_utf8</literal></entry>
2003        <entry><literal>JOHAB</literal></entry>
2004        <entry><literal>UTF8</literal></entry>
2005       </row>
2006
2007       <row>
2008        <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
2009        <entry><literal>KOI8</literal></entry>
2010        <entry><literal>ISO_8859_5</literal></entry>
2011       </row>
2012
2013       <row>
2014        <entry><literal>koi8_r_to_mic</literal></entry>
2015        <entry><literal>KOI8</literal></entry>
2016        <entry><literal>MULE_INTERNAL</literal></entry>
2017       </row>
2018
2019       <row>
2020        <entry><literal>koi8_r_to_utf8</literal></entry>
2021        <entry><literal>KOI8</literal></entry>
2022        <entry><literal>UTF8</literal></entry>
2023       </row>
2024
2025       <row>
2026        <entry><literal>koi8_r_to_windows_1251</literal></entry>
2027        <entry><literal>KOI8</literal></entry>
2028        <entry><literal>WIN1251</literal></entry>
2029       </row>
2030
2031       <row>
2032        <entry><literal>koi8_r_to_windows_866</literal></entry>
2033        <entry><literal>KOI8</literal></entry>
2034        <entry><literal>WIN866</literal></entry>
2035       </row>
2036
2037       <row>
2038        <entry><literal>mic_to_ascii</literal></entry>
2039        <entry><literal>MULE_INTERNAL</literal></entry>
2040        <entry><literal>SQL_ASCII</literal></entry>
2041       </row>
2042
2043       <row>
2044        <entry><literal>mic_to_big5</literal></entry>
2045        <entry><literal>MULE_INTERNAL</literal></entry>
2046        <entry><literal>BIG5</literal></entry>
2047       </row>
2048
2049       <row>
2050        <entry><literal>mic_to_euc_cn</literal></entry>
2051        <entry><literal>MULE_INTERNAL</literal></entry>
2052        <entry><literal>EUC_CN</literal></entry>
2053       </row>
2054
2055       <row>
2056        <entry><literal>mic_to_euc_jp</literal></entry>
2057        <entry><literal>MULE_INTERNAL</literal></entry>
2058        <entry><literal>EUC_JP</literal></entry>
2059       </row>
2060
2061       <row>
2062        <entry><literal>mic_to_euc_kr</literal></entry>
2063        <entry><literal>MULE_INTERNAL</literal></entry>
2064        <entry><literal>EUC_KR</literal></entry>
2065       </row>
2066
2067       <row>
2068        <entry><literal>mic_to_euc_tw</literal></entry>
2069        <entry><literal>MULE_INTERNAL</literal></entry>
2070        <entry><literal>EUC_TW</literal></entry>
2071       </row>
2072
2073       <row>
2074        <entry><literal>mic_to_iso_8859_1</literal></entry>
2075        <entry><literal>MULE_INTERNAL</literal></entry>
2076        <entry><literal>LATIN1</literal></entry>
2077       </row>
2078
2079       <row>
2080        <entry><literal>mic_to_iso_8859_2</literal></entry>
2081        <entry><literal>MULE_INTERNAL</literal></entry>
2082        <entry><literal>LATIN2</literal></entry>
2083       </row>
2084
2085       <row>
2086        <entry><literal>mic_to_iso_8859_3</literal></entry>
2087        <entry><literal>MULE_INTERNAL</literal></entry>
2088        <entry><literal>LATIN3</literal></entry>
2089       </row>
2090
2091       <row>
2092        <entry><literal>mic_to_iso_8859_4</literal></entry>
2093        <entry><literal>MULE_INTERNAL</literal></entry>
2094        <entry><literal>LATIN4</literal></entry>
2095       </row>
2096
2097       <row>
2098        <entry><literal>mic_to_iso_8859_5</literal></entry>
2099        <entry><literal>MULE_INTERNAL</literal></entry>
2100        <entry><literal>ISO_8859_5</literal></entry>
2101       </row>
2102
2103       <row>
2104        <entry><literal>mic_to_koi8_r</literal></entry>
2105        <entry><literal>MULE_INTERNAL</literal></entry>
2106        <entry><literal>KOI8</literal></entry>
2107       </row>
2108
2109       <row>
2110        <entry><literal>mic_to_sjis</literal></entry>
2111        <entry><literal>MULE_INTERNAL</literal></entry>
2112        <entry><literal>SJIS</literal></entry>
2113       </row>
2114
2115       <row>
2116        <entry><literal>mic_to_windows_1250</literal></entry>
2117        <entry><literal>MULE_INTERNAL</literal></entry>
2118        <entry><literal>WIN1250</literal></entry>
2119       </row>
2120
2121       <row>
2122        <entry><literal>mic_to_windows_1251</literal></entry>
2123        <entry><literal>MULE_INTERNAL</literal></entry>
2124        <entry><literal>WIN1251</literal></entry>
2125       </row>
2126
2127       <row>
2128        <entry><literal>mic_to_windows_866</literal></entry>
2129        <entry><literal>MULE_INTERNAL</literal></entry>
2130        <entry><literal>WIN866</literal></entry>
2131       </row>
2132
2133       <row>
2134        <entry><literal>sjis_to_euc_jp</literal></entry>
2135        <entry><literal>SJIS</literal></entry>
2136        <entry><literal>EUC_JP</literal></entry>
2137       </row>
2138
2139       <row>
2140        <entry><literal>sjis_to_mic</literal></entry>
2141        <entry><literal>SJIS</literal></entry>
2142        <entry><literal>MULE_INTERNAL</literal></entry>
2143       </row>
2144
2145       <row>
2146        <entry><literal>sjis_to_utf8</literal></entry>
2147        <entry><literal>SJIS</literal></entry>
2148        <entry><literal>UTF8</literal></entry>
2149       </row>
2150
2151       <row>
2152        <entry><literal>tcvn_to_utf8</literal></entry>
2153        <entry><literal>WIN1258</literal></entry>
2154        <entry><literal>UTF8</literal></entry>
2155       </row>
2156
2157       <row>
2158        <entry><literal>uhc_to_utf8</literal></entry>
2159        <entry><literal>UHC</literal></entry>
2160        <entry><literal>UTF8</literal></entry>
2161       </row>
2162
2163       <row>
2164        <entry><literal>utf8_to_ascii</literal></entry>
2165        <entry><literal>UTF8</literal></entry>
2166        <entry><literal>SQL_ASCII</literal></entry>
2167       </row>
2168
2169       <row>
2170        <entry><literal>utf8_to_big5</literal></entry>
2171        <entry><literal>UTF8</literal></entry>
2172        <entry><literal>BIG5</literal></entry>
2173       </row>
2174
2175       <row>
2176        <entry><literal>utf8_to_euc_cn</literal></entry>
2177        <entry><literal>UTF8</literal></entry>
2178        <entry><literal>EUC_CN</literal></entry>
2179       </row>
2180
2181       <row>
2182        <entry><literal>utf8_to_euc_jp</literal></entry>
2183        <entry><literal>UTF8</literal></entry>
2184        <entry><literal>EUC_JP</literal></entry>
2185       </row>
2186
2187       <row>
2188        <entry><literal>utf8_to_euc_kr</literal></entry>
2189        <entry><literal>UTF8</literal></entry>
2190        <entry><literal>EUC_KR</literal></entry>
2191       </row>
2192
2193       <row>
2194        <entry><literal>utf8_to_euc_tw</literal></entry>
2195        <entry><literal>UTF8</literal></entry>
2196        <entry><literal>EUC_TW</literal></entry>
2197       </row>
2198
2199       <row>
2200        <entry><literal>utf8_to_gb18030</literal></entry>
2201        <entry><literal>UTF8</literal></entry>
2202        <entry><literal>GB18030</literal></entry>
2203       </row>
2204
2205       <row>
2206        <entry><literal>utf8_to_gbk</literal></entry>
2207        <entry><literal>UTF8</literal></entry>
2208        <entry><literal>GBK</literal></entry>
2209       </row>
2210
2211       <row>
2212        <entry><literal>utf8_to_iso_8859_1</literal></entry>
2213        <entry><literal>UTF8</literal></entry>
2214        <entry><literal>LATIN1</literal></entry>
2215       </row>
2216
2217       <row>
2218        <entry><literal>utf8_to_iso_8859_10</literal></entry>
2219        <entry><literal>UTF8</literal></entry>
2220        <entry><literal>LATIN6</literal></entry>
2221       </row>
2222
2223       <row>
2224        <entry><literal>utf8_to_iso_8859_13</literal></entry>
2225        <entry><literal>UTF8</literal></entry>
2226        <entry><literal>LATIN7</literal></entry>
2227       </row>
2228
2229       <row>
2230        <entry><literal>utf8_to_iso_8859_14</literal></entry>
2231        <entry><literal>UTF8</literal></entry>
2232        <entry><literal>LATIN8</literal></entry>
2233       </row>
2234
2235       <row>
2236        <entry><literal>utf8_to_iso_8859_15</literal></entry>
2237        <entry><literal>UTF8</literal></entry>
2238        <entry><literal>LATIN9</literal></entry>
2239       </row>
2240
2241       <row>
2242        <entry><literal>utf8_to_iso_8859_16</literal></entry>
2243        <entry><literal>UTF8</literal></entry>
2244        <entry><literal>LATIN10</literal></entry>
2245       </row>
2246
2247       <row>
2248        <entry><literal>utf8_to_iso_8859_2</literal></entry>
2249        <entry><literal>UTF8</literal></entry>
2250        <entry><literal>LATIN2</literal></entry>
2251       </row>
2252
2253       <row>
2254        <entry><literal>utf8_to_iso_8859_3</literal></entry>
2255        <entry><literal>UTF8</literal></entry>
2256        <entry><literal>LATIN3</literal></entry>
2257       </row>
2258
2259       <row>
2260        <entry><literal>utf8_to_iso_8859_4</literal></entry>
2261        <entry><literal>UTF8</literal></entry>
2262        <entry><literal>LATIN4</literal></entry>
2263       </row>
2264
2265       <row>
2266        <entry><literal>utf8_to_iso_8859_5</literal></entry>
2267        <entry><literal>UTF8</literal></entry>
2268        <entry><literal>ISO_8859_5</literal></entry>
2269       </row>
2270
2271       <row>
2272        <entry><literal>utf8_to_iso_8859_6</literal></entry>
2273        <entry><literal>UTF8</literal></entry>
2274        <entry><literal>ISO_8859_6</literal></entry>
2275       </row>
2276
2277       <row>
2278        <entry><literal>utf8_to_iso_8859_7</literal></entry>
2279        <entry><literal>UTF8</literal></entry>
2280        <entry><literal>ISO_8859_7</literal></entry>
2281       </row>
2282
2283       <row>
2284        <entry><literal>utf8_to_iso_8859_8</literal></entry>
2285        <entry><literal>UTF8</literal></entry>
2286        <entry><literal>ISO_8859_8</literal></entry>
2287       </row>
2288
2289       <row>
2290        <entry><literal>utf8_to_iso_8859_9</literal></entry>
2291        <entry><literal>UTF8</literal></entry>
2292        <entry><literal>LATIN5</literal></entry>
2293       </row>
2294
2295       <row>
2296        <entry><literal>utf8_to_johab</literal></entry>
2297        <entry><literal>UTF8</literal></entry>
2298        <entry><literal>JOHAB</literal></entry>
2299       </row>
2300
2301       <row>
2302        <entry><literal>utf8_to_koi8_r</literal></entry>
2303        <entry><literal>UTF8</literal></entry>
2304        <entry><literal>KOI8</literal></entry>
2305       </row>
2306
2307       <row>
2308        <entry><literal>utf8_to_sjis</literal></entry>
2309        <entry><literal>UTF8</literal></entry>
2310        <entry><literal>SJIS</literal></entry>
2311       </row>
2312
2313       <row>
2314        <entry><literal>utf8_to_tcvn</literal></entry>
2315        <entry><literal>UTF8</literal></entry>
2316        <entry><literal>WIN1258</literal></entry>
2317       </row>
2318
2319       <row>
2320        <entry><literal>utf8_to_uhc</literal></entry>
2321        <entry><literal>UTF8</literal></entry>
2322        <entry><literal>UHC</literal></entry>
2323       </row>
2324
2325       <row>
2326        <entry><literal>utf8_to_windows_1250</literal></entry>
2327        <entry><literal>UTF8</literal></entry>
2328        <entry><literal>WIN1250</literal></entry>
2329       </row>
2330
2331       <row>
2332        <entry><literal>utf8_to_windows_1251</literal></entry>
2333        <entry><literal>UTF8</literal></entry>
2334        <entry><literal>WIN1251</literal></entry>
2335       </row>
2336
2337       <row>
2338        <entry><literal>utf8_to_windows_1252</literal></entry>
2339        <entry><literal>UTF8</literal></entry>
2340        <entry><literal>WIN1252</literal></entry>
2341       </row>
2342
2343       <row>
2344        <entry><literal>utf8_to_windows_1253</literal></entry>
2345        <entry><literal>UTF8</literal></entry>
2346        <entry><literal>WIN1253</literal></entry>
2347       </row>
2348
2349       <row>
2350        <entry><literal>utf8_to_windows_1254</literal></entry>
2351        <entry><literal>UTF8</literal></entry>
2352        <entry><literal>WIN1254</literal></entry>
2353       </row>
2354
2355       <row>
2356        <entry><literal>utf8_to_windows_1255</literal></entry>
2357        <entry><literal>UTF8</literal></entry>
2358        <entry><literal>WIN1255</literal></entry>
2359       </row>
2360
2361       <row>
2362        <entry><literal>utf8_to_windows_1256</literal></entry>
2363        <entry><literal>UTF8</literal></entry>
2364        <entry><literal>WIN1256</literal></entry>
2365       </row>
2366
2367       <row>
2368        <entry><literal>utf8_to_windows_1257</literal></entry>
2369        <entry><literal>UTF8</literal></entry>
2370        <entry><literal>WIN1257</literal></entry>
2371       </row>
2372
2373       <row>
2374        <entry><literal>utf8_to_windows_866</literal></entry>
2375        <entry><literal>UTF8</literal></entry>
2376        <entry><literal>WIN866</literal></entry>
2377       </row>
2378
2379       <row>
2380        <entry><literal>utf8_to_windows_874</literal></entry>
2381        <entry><literal>UTF8</literal></entry>
2382        <entry><literal>WIN874</literal></entry>
2383       </row>
2384
2385       <row>
2386        <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
2387        <entry><literal>WIN1250</literal></entry>
2388        <entry><literal>LATIN2</literal></entry>
2389       </row>
2390
2391       <row>
2392        <entry><literal>windows_1250_to_mic</literal></entry>
2393        <entry><literal>WIN1250</literal></entry>
2394        <entry><literal>MULE_INTERNAL</literal></entry>
2395       </row>
2396
2397       <row>
2398        <entry><literal>windows_1250_to_utf8</literal></entry>
2399        <entry><literal>WIN1250</literal></entry>
2400        <entry><literal>UTF8</literal></entry>
2401       </row>
2402
2403       <row>
2404        <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
2405        <entry><literal>WIN1251</literal></entry>
2406        <entry><literal>ISO_8859_5</literal></entry>
2407       </row>
2408
2409       <row>
2410        <entry><literal>windows_1251_to_koi8_r</literal></entry>
2411        <entry><literal>WIN1251</literal></entry>
2412        <entry><literal>KOI8</literal></entry>
2413       </row>
2414
2415       <row>
2416        <entry><literal>windows_1251_to_mic</literal></entry>
2417        <entry><literal>WIN1251</literal></entry>
2418        <entry><literal>MULE_INTERNAL</literal></entry>
2419       </row>
2420
2421       <row>
2422        <entry><literal>windows_1251_to_utf8</literal></entry>
2423        <entry><literal>WIN1251</literal></entry>
2424        <entry><literal>UTF8</literal></entry>
2425       </row>
2426
2427       <row>
2428        <entry><literal>windows_1251_to_windows_866</literal></entry>
2429        <entry><literal>WIN1251</literal></entry>
2430        <entry><literal>WIN866</literal></entry>
2431       </row>
2432
2433       <row>
2434        <entry><literal>windows_1252_to_utf8</literal></entry>
2435        <entry><literal>WIN1252</literal></entry>
2436        <entry><literal>UTF8</literal></entry>
2437       </row>
2438
2439       <row>
2440        <entry><literal>windows_1256_to_utf8</literal></entry>
2441        <entry><literal>WIN1256</literal></entry>
2442        <entry><literal>UTF8</literal></entry>
2443       </row>
2444
2445       <row>
2446        <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2447        <entry><literal>WIN866</literal></entry>
2448        <entry><literal>ISO_8859_5</literal></entry>
2449       </row>
2450
2451       <row>
2452        <entry><literal>windows_866_to_koi8_r</literal></entry>
2453        <entry><literal>WIN866</literal></entry>
2454        <entry><literal>KOI8</literal></entry>
2455       </row>
2456
2457       <row>
2458        <entry><literal>windows_866_to_mic</literal></entry>
2459        <entry><literal>WIN866</literal></entry>
2460        <entry><literal>MULE_INTERNAL</literal></entry>
2461       </row>
2462
2463       <row>
2464        <entry><literal>windows_866_to_utf8</literal></entry>
2465        <entry><literal>WIN866</literal></entry>
2466        <entry><literal>UTF8</literal></entry>
2467       </row>
2468
2469       <row>
2470        <entry><literal>windows_866_to_windows_1251</literal></entry>
2471        <entry><literal>WIN866</literal></entry>
2472        <entry><literal>WIN</literal></entry>
2473       </row>
2474
2475       <row>
2476        <entry><literal>windows_874_to_utf8</literal></entry>
2477        <entry><literal>WIN874</literal></entry>
2478        <entry><literal>UTF8</literal></entry>
2479       </row>
2480
2481       <row>
2482        <entry><literal>euc_jis_2004_to_utf8</literal></entry>
2483        <entry><literal>EUC_JIS_2004</literal></entry>
2484        <entry><literal>UTF8</literal></entry>
2485       </row>
2486
2487       <row>
2488        <entry><literal>ut8_to_euc_jis_2004</literal></entry>
2489        <entry><literal>UTF8</literal></entry>
2490        <entry><literal>EUC_JIS_2004</literal></entry>
2491       </row>
2492
2493       <row>
2494        <entry><literal>shift_jis_2004_to_utf8</literal></entry>
2495        <entry><literal>SHIFT_JIS_2004</literal></entry>
2496        <entry><literal>UTF8</literal></entry>
2497       </row>
2498
2499       <row>
2500        <entry><literal>ut8_to_shift_jis_2004</literal></entry>
2501        <entry><literal>UTF8</literal></entry>
2502        <entry><literal>SHIFT_JIS_2004</literal></entry>
2503       </row>
2504
2505       <row>
2506        <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
2507        <entry><literal>EUC_JIS_2004</literal></entry>
2508        <entry><literal>SHIFT_JIS_2004</literal></entry>
2509       </row>
2510
2511       <row>
2512        <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
2513        <entry><literal>SHIFT_JIS_2004</literal></entry>
2514        <entry><literal>EUC_JIS_2004</literal></entry>
2515       </row>
2516
2517      </tbody>
2518     </tgroup>
2519    </table>
2520
2521   </sect1>
2522
2523
2524   <sect1 id="functions-binarystring">
2525    <title>Binary String Functions and Operators</title>
2526
2527    <indexterm zone="functions-binarystring">
2528     <primary>binary data</primary>
2529     <secondary>functions</secondary>
2530    </indexterm>
2531
2532    <para>
2533     This section describes functions and operators for examining and
2534     manipulating values of type <type>bytea</type>.
2535    </para>
2536
2537    <para>
2538     <acronym>SQL</acronym> defines some string functions with a
2539     special syntax where 
2540     certain key words rather than commas are used to separate the
2541     arguments.  Details are in
2542     <xref linkend="functions-binarystring-sql">.
2543     Some functions are also implemented using the regular syntax for
2544     function invocation.
2545     (See <xref linkend="functions-binarystring-other">.)
2546    </para>
2547
2548    <table id="functions-binarystring-sql">
2549     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
2550     <tgroup cols="5">
2551      <thead>
2552       <row>
2553        <entry>Function</entry>
2554        <entry>Return Type</entry>
2555        <entry>Description</entry>
2556        <entry>Example</entry>
2557        <entry>Result</entry>  
2558       </row>
2559      </thead>
2560
2561      <tbody>
2562       <row>
2563        <entry><literal><parameter>string</parameter> <literal>||</literal>
2564         <parameter>string</parameter></literal></entry>
2565        <entry> <type>bytea</type> </entry>
2566        <entry>
2567         String concatenation
2568         <indexterm>
2569          <primary>binary string</primary>
2570          <secondary>concatenation</secondary>
2571         </indexterm>
2572        </entry>
2573        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
2574        <entry><literal>\\Post'gres\000</literal></entry>
2575       </row>
2576
2577       <row>
2578        <entry><function>get_bit</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2579        <entry><type>int</type></entry>
2580        <entry>
2581         Extract bit from string
2582         <indexterm>
2583          <primary>get_bit</primary>
2584         </indexterm>
2585        </entry>
2586        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
2587        <entry><literal>1</literal></entry>
2588       </row>
2589
2590       <row>
2591        <entry><function>get_byte</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2592        <entry><type>int</type></entry>
2593        <entry>
2594         Extract byte from string
2595         <indexterm>
2596          <primary>get_byte</primary>
2597         </indexterm>
2598        </entry>
2599        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
2600        <entry><literal>109</literal></entry>
2601       </row>
2602
2603       <row>
2604        <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
2605        <entry><type>int</type></entry>
2606        <entry>Number of bytes in binary string</entry>
2607        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
2608        <entry><literal>5</literal></entry>
2609       </row>
2610
2611       <row>
2612        <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
2613        <entry><type>int</type></entry>
2614        <entry>Location of specified substring</entry>
2615       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
2616        <entry><literal>3</literal></entry>
2617       </row>
2618
2619       <row>
2620        <entry><function>set_bit</function>(<parameter>string</parameter>,
2621        <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2622        <entry><type>bytea</type></entry>
2623        <entry>
2624         Set bit in string
2625         <indexterm>
2626          <primary>set_bit</primary>
2627         </indexterm>
2628        </entry>
2629        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
2630        <entry><literal>Th\000omAs</literal></entry>
2631       </row>
2632
2633       <row>
2634        <entry><function>set_byte</function>(<parameter>string</parameter>,
2635        <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2636        <entry><type>bytea</type></entry>
2637        <entry>
2638         Set byte in string
2639         <indexterm>
2640          <primary>set_byte</primary>
2641         </indexterm>
2642        </entry>
2643        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
2644        <entry><literal>Th\000o@as</literal></entry>
2645       </row>
2646
2647       <row>
2648        <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
2649        <entry><type>bytea</type></entry>
2650        <entry>
2651         Extract substring
2652         <indexterm>
2653          <primary>substring</primary>
2654         </indexterm>
2655        </entry>
2656        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
2657        <entry><literal>h\000o</literal></entry>
2658       </row>
2659
2660       <row>
2661        <entry>
2662         <literal><function>trim</function>(<optional>both</optional>
2663         <parameter>bytes</parameter> from
2664         <parameter>string</parameter>)</literal>
2665        </entry>
2666        <entry><type>bytea</type></entry>
2667        <entry>
2668         Remove the longest string containing only the bytes in
2669         <parameter>bytes</parameter> from the start
2670         and end of <parameter>string</parameter>
2671        </entry>
2672        <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
2673        <entry><literal>Tom</literal></entry>
2674       </row>
2675      </tbody>
2676     </tgroup>
2677    </table>
2678
2679    <para>
2680     Additional binary string manipulation functions are available and
2681     are listed in <xref linkend="functions-binarystring-other">.  Some
2682     of them are used internally to implement the
2683     <acronym>SQL</acronym>-standard string functions listed in <xref
2684     linkend="functions-binarystring-sql">.
2685    </para>
2686
2687    <table id="functions-binarystring-other">
2688     <title>Other Binary String Functions</title>
2689     <tgroup cols="5">
2690      <thead>
2691       <row>
2692        <entry>Function</entry>
2693        <entry>Return Type</entry>
2694        <entry>Description</entry>
2695        <entry>Example</entry>
2696        <entry>Result</entry>
2697       </row>
2698      </thead>
2699
2700      <tbody>
2701       <row>
2702        <entry><literal><function>btrim</function>(<parameter>string</parameter>
2703         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</literal></entry>
2704        <entry><type>bytea</type></entry>
2705        <entry>
2706         Remove the longest string consisting only of bytes
2707         in <parameter>bytes</parameter> from the start and end of
2708         <parameter>string</parameter>
2709       </entry>
2710       <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
2711       <entry><literal>trim</literal></entry>
2712      </row>
2713
2714      <row>
2715       <entry>
2716        <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
2717               <parameter>type</parameter> <type>text</type>)</literal>
2718       </entry>
2719       <entry><type>bytea</type></entry>
2720       <entry>
2721        Decode binary string from <parameter>string</parameter> previously 
2722        encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
2723       </entry>
2724       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
2725       <entry><literal>123\000456</literal></entry>
2726      </row>
2727
2728      <row>
2729       <entry>
2730        <literal><function>encode</function>(<parameter>string</parameter> <type>bytea</type>,
2731               <parameter>type</parameter> <type>text</type>)</literal>
2732       </entry>
2733       <entry><type>text</type></entry>
2734       <entry>
2735        Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
2736        types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
2737       </entry>
2738       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
2739       <entry><literal>123\000456</literal></entry>
2740      </row>
2741
2742      <row>
2743       <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
2744       <entry><type>int</type></entry>
2745       <entry>
2746        Length of binary string
2747        <indexterm>
2748         <primary>binary string</primary>
2749         <secondary>length</secondary>
2750        </indexterm>
2751        <indexterm>
2752         <primary>length</primary>
2753         <secondary sortas="binary string">of a binary string</secondary>
2754         <see>binary strings, length</see>
2755        </indexterm>
2756       </entry>
2757       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
2758       <entry><literal>5</literal></entry>
2759      </row>
2760
2761      <row>
2762       <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
2763       <entry><type>text</type></entry>
2764       <entry>
2765        Calculates the MD5 hash of <parameter>string</parameter>,
2766        returning the result in hexadecimal
2767       </entry>
2768       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
2769       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
2770      </row>
2771     </tbody>
2772    </tgroup>
2773   </table>
2774
2775  </sect1>
2776
2777
2778   <sect1 id="functions-bitstring">
2779    <title>Bit String Functions and Operators</title>
2780
2781    <indexterm zone="functions-bitstring">
2782     <primary>bit strings</primary>
2783     <secondary>functions</secondary>
2784    </indexterm>
2785
2786    <para>
2787     This section describes functions and operators for examining and
2788     manipulating bit strings, that is values of the types
2789     <type>bit</type> and <type>bit varying</type>.  Aside from the
2790     usual comparison operators, the operators
2791     shown in <xref linkend="functions-bit-string-op-table"> can be used.
2792     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
2793     and <literal>#</literal> must be of equal length.  When bit
2794     shifting, the original length of the string is preserved, as shown
2795     in the examples.
2796    </para>
2797
2798    <table id="functions-bit-string-op-table">
2799     <title>Bit String Operators</title>
2800
2801     <tgroup cols="4">
2802      <thead>
2803       <row>
2804        <entry>Operator</entry>
2805        <entry>Description</entry>
2806        <entry>Example</entry>
2807        <entry>Result</entry>
2808       </row>
2809      </thead>
2810
2811      <tbody>
2812       <row>
2813        <entry> <literal>||</literal> </entry>
2814        <entry>concatenation</entry>
2815        <entry><literal>B'10001' || B'011'</literal></entry>
2816        <entry><literal>10001011</literal></entry>
2817       </row>
2818
2819       <row>
2820        <entry> <literal>&amp;</literal> </entry>
2821        <entry>bitwise AND</entry>
2822        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
2823        <entry><literal>00001</literal></entry>
2824       </row>
2825
2826       <row>
2827        <entry> <literal>|</literal> </entry>
2828        <entry>bitwise OR</entry>
2829        <entry><literal>B'10001' | B'01101'</literal></entry>
2830        <entry><literal>11101</literal></entry>
2831       </row>
2832
2833       <row>
2834        <entry> <literal>#</literal> </entry>
2835        <entry>bitwise XOR</entry>
2836        <entry><literal>B'10001' # B'01101'</literal></entry>
2837        <entry><literal>11100</literal></entry>
2838       </row>
2839
2840       <row>
2841        <entry> <literal>~</literal> </entry>
2842        <entry>bitwise NOT</entry>
2843        <entry><literal>~ B'10001'</literal></entry>
2844        <entry><literal>01110</literal></entry>
2845       </row>
2846
2847       <row>
2848        <entry> <literal>&lt;&lt;</literal> </entry>
2849        <entry>bitwise shift left</entry>
2850        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
2851        <entry><literal>01000</literal></entry>
2852       </row>
2853
2854       <row>
2855        <entry> <literal>&gt;&gt;</literal> </entry>
2856        <entry>bitwise shift right</entry>
2857        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
2858        <entry><literal>00100</literal></entry>
2859       </row>
2860      </tbody>
2861     </tgroup>
2862    </table>
2863
2864    <para>
2865     The following <acronym>SQL</acronym>-standard functions work on bit
2866     strings as well as character strings:
2867     <literal><function>length</function></literal>,
2868     <literal><function>bit_length</function></literal>,
2869     <literal><function>octet_length</function></literal>,
2870     <literal><function>position</function></literal>,
2871     <literal><function>substring</function></literal>.
2872    </para>
2873
2874    <para>
2875     In addition, it is possible to cast integral values to and from type
2876     <type>bit</>.
2877     Some examples:
2878 <programlisting>
2879 44::bit(10)                    <lineannotation>0000101100</lineannotation>
2880 44::bit(3)                     <lineannotation>100</lineannotation>
2881 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
2882 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
2883 </programlisting>
2884     Note that casting to just <quote>bit</> means casting to
2885     <literal>bit(1)</>, and so it will deliver only the least significant
2886     bit of the integer.
2887    </para>
2888
2889     <note>
2890      <para>
2891       Prior to <productname>PostgreSQL</productname> 8.0, casting an
2892       integer to <type>bit(n)</> would copy the leftmost <literal>n</>
2893       bits of the integer, whereas now it copies the rightmost <literal>n</>
2894       bits.  Also, casting an integer to a bit string width wider than
2895       the integer itself will sign-extend on the left.
2896      </para>
2897     </note>
2898
2899   </sect1>
2900
2901
2902  <sect1 id="functions-matching">
2903   <title>Pattern Matching</title>
2904
2905   <indexterm zone="functions-matching">
2906    <primary>pattern matching</primary>
2907   </indexterm>
2908
2909    <para>
2910     There are three separate approaches to pattern matching provided
2911     by <productname>PostgreSQL</productname>: the traditional
2912     <acronym>SQL</acronym> <function>LIKE</function> operator, the
2913     more recent <function>SIMILAR TO</function> operator (added in
2914     SQL:1999), and <acronym>POSIX</acronym>-style regular
2915     expressions.  Aside from the basic <quote>does this string match
2916     this pattern?</> operators, functions are available to extract
2917     or replace matching substrings and to split a string at the matches.
2918    </para>
2919
2920    <tip>
2921     <para>
2922      If you have pattern matching needs that go beyond this,
2923      consider writing a user-defined function in Perl or Tcl.
2924     </para>
2925    </tip>
2926
2927   <sect2 id="functions-like">
2928    <title><function>LIKE</function></title>
2929
2930    <indexterm>
2931     <primary>LIKE</primary>
2932    </indexterm>
2933
2934 <synopsis>
2935 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
2936 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
2937 </synopsis>
2938
2939     <para>
2940      Every <replaceable>pattern</replaceable> defines a set of strings.
2941      The <function>LIKE</function> expression returns true if the
2942      <replaceable>string</replaceable> is contained in the set of
2943      strings represented by <replaceable>pattern</replaceable>.  (As
2944      expected, the <function>NOT LIKE</function> expression returns
2945      false if <function>LIKE</function> returns true, and vice versa.
2946      An equivalent expression is
2947      <literal>NOT (<replaceable>string</replaceable> LIKE
2948       <replaceable>pattern</replaceable>)</literal>.)
2949     </para>
2950
2951     <para>
2952      If <replaceable>pattern</replaceable> does not contain percent
2953      signs or underscore, then the pattern only represents the string
2954      itself; in that case <function>LIKE</function> acts like the
2955      equals operator.  An underscore (<literal>_</literal>) in
2956      <replaceable>pattern</replaceable> stands for (matches) any single
2957      character; a percent sign (<literal>%</literal>) matches any string
2958      of zero or more characters.
2959     </para>
2960
2961    <para>
2962     Some examples:
2963 <programlisting>
2964 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
2965 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
2966 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
2967 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
2968 </programlisting>
2969    </para>
2970    
2971    <para>
2972     <function>LIKE</function> pattern matches always cover the entire
2973     string.  To match a sequence anywhere within a string, the
2974     pattern must therefore start and end with a percent sign.
2975    </para>
2976
2977    <para>
2978     To match a literal underscore or percent sign without matching
2979     other characters, the respective character in
2980     <replaceable>pattern</replaceable> must be 
2981     preceded by the escape character.  The default escape
2982     character is the backslash but a different one can be selected by
2983     using the <literal>ESCAPE</literal> clause.  To match the escape
2984     character itself, write two escape characters.
2985    </para>
2986
2987    <para>
2988     Note that the backslash already has a special meaning in string literals,
2989     so to write a pattern constant that contains a backslash you must write two
2990     backslashes in an SQL statement (assuming escape string syntax is used, see
2991     <xref linkend="sql-syntax-strings">).  Thus, writing a pattern that
2992     actually matches a literal backslash means writing four backslashes in the
2993     statement.  You can avoid this by selecting a different escape character
2994     with <literal>ESCAPE</literal>; then a backslash is not special to
2995     <function>LIKE</function> anymore. (But it is still special to the string
2996     literal parser, so you still need two of them.)
2997    </para>
2998
2999    <para>
3000     It's also possible to select no escape character by writing
3001     <literal>ESCAPE ''</literal>.  This effectively disables the
3002     escape mechanism, which makes it impossible to turn off the
3003     special meaning of underscore and percent signs in the pattern.
3004    </para>
3005
3006    <para>
3007     The key word <token>ILIKE</token> can be used instead of
3008     <token>LIKE</token> to make the match case-insensitive according
3009     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3010     <productname>PostgreSQL</productname> extension.
3011    </para>
3012
3013    <para>
3014     The operator <literal>~~</literal> is equivalent to
3015     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3016     <function>ILIKE</function>.  There are also
3017     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3018     represent <function>NOT LIKE</function> and <function>NOT
3019     ILIKE</function>, respectively.  All of these operators are
3020     <productname>PostgreSQL</productname>-specific.
3021    </para>
3022   </sect2>
3023
3024
3025   <sect2 id="functions-similarto-regexp">
3026    <title><function>SIMILAR TO</function> Regular Expressions</title>
3027
3028    <indexterm>
3029     <primary>regular expression</primary>
3030     <!-- <seealso>pattern matching</seealso> breaks index build -->
3031    </indexterm>
3032
3033    <indexterm>
3034     <primary>SIMILAR TO</primary>
3035    </indexterm>
3036    <indexterm>
3037     <primary>substring</primary>
3038    </indexterm>
3039
3040 <synopsis>
3041 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3042 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3043 </synopsis>
3044
3045    <para>
3046     The <function>SIMILAR TO</function> operator returns true or
3047     false depending on whether its pattern matches the given string.
3048     It is much like <function>LIKE</function>, except that it
3049     interprets the pattern using the SQL standard's definition of a
3050     regular expression.  SQL regular expressions are a curious cross
3051     between <function>LIKE</function> notation and common regular
3052     expression notation.
3053    </para>
3054
3055    <para>
3056     Like <function>LIKE</function>, the  <function>SIMILAR TO</function>
3057     operator succeeds only if its pattern matches the entire string;
3058     this is unlike common regular expression practice, wherein the pattern
3059     can match any part of the string.
3060     Also like
3061     <function>LIKE</function>, <function>SIMILAR TO</function> uses
3062     <literal>_</> and <literal>%</> as wildcard characters denoting
3063     any single character and any string, respectively (these are
3064     comparable to <literal>.</> and <literal>.*</> in POSIX regular
3065     expressions).
3066    </para>
3067
3068    <para>
3069     In addition to these facilities borrowed from <function>LIKE</function>,
3070     <function>SIMILAR TO</function> supports these pattern-matching
3071     metacharacters borrowed from POSIX regular expressions:
3072
3073    <itemizedlist>
3074     <listitem>
3075      <para>
3076       <literal>|</literal> denotes alternation (either of two alternatives).
3077      </para>
3078     </listitem>
3079     <listitem>
3080      <para>
3081       <literal>*</literal> denotes repetition of the previous item zero
3082       or more times.
3083      </para>
3084     </listitem>
3085     <listitem>
3086      <para>
3087       <literal>+</literal> denotes repetition of the previous item one
3088       or more times.
3089      </para>
3090     </listitem>
3091     <listitem>
3092      <para>
3093       Parentheses <literal>()</literal> can be used to group items into
3094       a single logical item.
3095      </para>
3096     </listitem>
3097     <listitem>
3098      <para>
3099       A bracket expression <literal>[...]</literal> specifies a character
3100       class, just as in POSIX regular expressions.
3101      </para>
3102     </listitem>
3103    </itemizedlist>
3104
3105     Notice that bounded repetition (<literal>?</> and <literal>{...}</>)
3106     are not provided, though they exist in POSIX.  Also, the dot (<literal>.</>)
3107     is not a metacharacter.
3108    </para>
3109
3110    <para>
3111     As with <function>LIKE</>, a backslash disables the special meaning
3112     of any of these metacharacters; or a different escape character can
3113     be specified with <literal>ESCAPE</>.
3114    </para>
3115
3116    <para>
3117     Some examples:
3118 <programlisting>
3119 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
3120 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
3121 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
3122 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
3123 </programlisting>
3124    </para>
3125
3126    <para>
3127     The <function>substring</> function with three parameters,
3128     <function>substring(<replaceable>string</replaceable> from
3129     <replaceable>pattern</replaceable> for
3130     <replaceable>escape-character</replaceable>)</function>, provides
3131     extraction of a substring that matches an SQL
3132     regular expression pattern.  As with <literal>SIMILAR TO</>, the
3133     specified pattern must match to the entire data string, else the
3134     function fails and returns null.  To indicate the part of the
3135     pattern that should be returned on success, the pattern must contain
3136     two occurrences of the escape character followed by a double quote
3137     (<literal>"</>).  The text matching the portion of the pattern
3138     between these markers is returned.
3139    </para>
3140
3141    <para>
3142     Some examples:
3143 <programlisting>
3144 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
3145 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
3146 </programlisting>
3147    </para>
3148   </sect2>
3149
3150   <sect2 id="functions-posix-regexp">
3151    <title><acronym>POSIX</acronym> Regular Expressions</title>
3152
3153    <indexterm zone="functions-posix-regexp">
3154     <primary>regular expression</primary>
3155     <seealso>pattern matching</seealso>
3156    </indexterm>
3157    <indexterm>
3158     <primary>substring</primary>
3159    </indexterm>
3160    <indexterm>
3161     <primary>regexp_replace</primary>
3162    </indexterm>
3163    <indexterm>
3164     <primary>regexp_matches</primary>
3165    </indexterm>
3166    <indexterm>
3167     <primary>regexp_split_to_table</primary>
3168    </indexterm>
3169    <indexterm>
3170     <primary>regexp_split_to_array</primary>
3171    </indexterm>
3172
3173    <para>
3174     <xref linkend="functions-posix-table"> lists the available
3175     operators for pattern matching using POSIX regular expressions.
3176    </para>
3177
3178    <table id="functions-posix-table">
3179     <title>Regular Expression Match Operators</title>
3180
3181     <tgroup cols="3">
3182      <thead>
3183       <row>
3184        <entry>Operator</entry>
3185        <entry>Description</entry>
3186        <entry>Example</entry>
3187       </row>
3188      </thead>
3189
3190       <tbody>
3191        <row>
3192         <entry> <literal>~</literal> </entry>
3193         <entry>Matches regular expression, case sensitive</entry>
3194         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3195        </row>
3196
3197        <row>
3198         <entry> <literal>~*</literal> </entry>
3199         <entry>Matches regular expression, case insensitive</entry>
3200         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3201        </row>
3202
3203        <row>
3204         <entry> <literal>!~</literal> </entry>
3205         <entry>Does not match regular expression, case sensitive</entry>
3206         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3207        </row>
3208
3209        <row>
3210         <entry> <literal>!~*</literal> </entry>
3211         <entry>Does not match regular expression, case insensitive</entry>
3212         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3213        </row>
3214       </tbody>
3215      </tgroup>
3216     </table>
3217
3218     <para>
3219      <acronym>POSIX</acronym> regular expressions provide a more
3220      powerful means for 
3221      pattern matching than the <function>LIKE</function> and
3222      <function>SIMILAR TO</> operators.
3223      Many Unix tools such as <command>egrep</command>,
3224      <command>sed</command>, or <command>awk</command> use a pattern
3225      matching language that is similar to the one described here.
3226     </para>
3227
3228     <para>
3229      A regular expression is a character sequence that is an
3230      abbreviated definition of a set of strings (a <firstterm>regular
3231      set</firstterm>).  A string is said to match a regular expression
3232      if it is a member of the regular set described by the regular
3233      expression.  As with <function>LIKE</function>, pattern characters
3234      match string characters exactly unless they are special characters
3235      in the regular expression language &mdash; but regular expressions use
3236      different special characters than <function>LIKE</function> does.
3237      Unlike <function>LIKE</function> patterns, a
3238      regular expression is allowed to match anywhere within a string, unless
3239      the regular expression is explicitly anchored to the beginning or
3240      end of the string.
3241     </para>
3242
3243     <para>
3244      Some examples:
3245 <programlisting>
3246 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
3247 'abc' ~ '^a'     <lineannotation>true</lineannotation>
3248 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
3249 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3250 </programlisting>
3251     </para>
3252
3253     <para>
3254      The <acronym>POSIX</acronym> pattern language is described in much
3255      greater detail below.
3256     </para>
3257
3258     <para>
3259      The <function>substring</> function with two parameters,
3260      <function>substring(<replaceable>string</replaceable> from
3261      <replaceable>pattern</replaceable>)</function>, provides extraction of a
3262      substring
3263      that matches a POSIX regular expression pattern.  It returns null if
3264      there is no match, otherwise the portion of the text that matched the
3265      pattern.  But if the pattern contains any parentheses, the portion
3266      of the text that matched the first parenthesized subexpression (the
3267      one whose left parenthesis comes first) is
3268      returned.  You can put parentheses around the whole expression
3269      if you want to use parentheses within it without triggering this
3270      exception.  If you need parentheses in the pattern before the
3271      subexpression you want to extract, see the non-capturing parentheses
3272      described below.
3273     </para>
3274
3275    <para>
3276     Some examples:
3277 <programlisting>
3278 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
3279 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
3280 </programlisting>
3281    </para>
3282
3283     <para>
3284      The <function>regexp_replace</> function provides substitution of
3285      new text for substrings that match POSIX regular expression patterns.
3286      It has the syntax
3287      <function>regexp_replace</function>(<replaceable>source</>,
3288      <replaceable>pattern</>, <replaceable>replacement</>
3289      <optional>, <replaceable>flags</> </optional>).
3290      The <replaceable>source</> string is returned unchanged if
3291      there is no match to the <replaceable>pattern</>.  If there is a
3292      match, the <replaceable>source</> string is returned with the
3293      <replaceable>replacement</> string substituted for the matching
3294      substring.  The <replaceable>replacement</> string can contain
3295      <literal>\</><replaceable>n</>, where <replaceable>n</> is <literal>1</>
3296      through <literal>9</>, to indicate that the source substring matching the
3297      <replaceable>n</>'th parenthesized subexpression of the pattern should be
3298      inserted, and it can contain <literal>\&amp;</> to indicate that the
3299      substring matching the entire pattern should be inserted.  Write
3300      <literal>\\</> if you need to put a literal backslash in the replacement
3301      text.  (As always, remember to double backslashes written in literal
3302      constant strings, assuming escape string syntax is used.)
3303      The <replaceable>flags</> parameter is an optional text
3304      string containing zero or more single-letter flags that change the
3305      function's behavior.  Flag <literal>i</> specifies case-insensitive
3306      matching, while flag <literal>g</> specifies replacement of each matching
3307      substring rather than only the first one.  Other supported flags are
3308      described in <xref linkend="posix-embedded-options-table">.
3309     </para>
3310
3311    <para>
3312     Some examples:
3313 <programlisting>
3314 regexp_replace('foobarbaz', 'b..', 'X')
3315                                    <lineannotation>fooXbaz</lineannotation>
3316 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3317                                    <lineannotation>fooXX</lineannotation>
3318 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3319                                    <lineannotation>fooXarYXazY</lineannotation>
3320 </programlisting>
3321    </para>
3322
3323     <para>
3324      The <function>regexp_matches</> function returns all of the captured
3325      substrings resulting from matching a POSIX regular expression pattern.
3326      It has the syntax
3327      <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3328      <optional>, <replaceable>flags</> </optional>).
3329      If there is no match to the <replaceable>pattern</>, the function returns
3330      no rows.  If there is a match, the function returns a text array whose
3331      <replaceable>n</>'th element is the substring matching the
3332      <replaceable>n</>'th parenthesized subexpression of the pattern
3333      (not counting <quote>non-capturing</> parentheses; see below for
3334      details).  If the pattern does not contain any parenthesized
3335      subexpressions, then the result is a single-element text array containing
3336      the substring matching the whole pattern.
3337      The <replaceable>flags</> parameter is an optional text
3338      string containing zero or more single-letter flags that change the
3339      function's behavior.  Flag <literal>g</> causes the function to find
3340      each match in the string, not only the first one, and return a row for
3341      each such match.  Other supported
3342      flags are described in <xref linkend="posix-embedded-options-table">.
3343     </para>
3344
3345    <para>
3346     Some examples:
3347 <programlisting>
3348 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3349  regexp_matches 
3350 ----------------
3351  {bar,beque}
3352 (1 row)
3353
3354 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3355  regexp_matches 
3356 ----------------
3357  {bar,beque}
3358  {bazil,barf}
3359 (2 rows)
3360
3361 SELECT regexp_matches('foobarbequebaz', 'barbeque');
3362  regexp_matches 
3363 ----------------
3364  {barbeque}
3365 (1 row)
3366 </programlisting>
3367    </para>
3368
3369     <para>
3370      The <function>regexp_split_to_table</> function splits a string using a POSIX
3371      regular expression pattern as a delimiter.  It has the syntax
3372      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
3373      <optional>, <replaceable>flags</> </optional>).
3374      If there is no match to the <replaceable>pattern</>, the function returns the
3375      <replaceable>string</>.  If there is at least one match, for each match it returns
3376      the text from the end of the last match (or the beginning of the string)
3377      to the beginning of the match.  When there are no more matches, it
3378      returns the text from the end of the last match to the end of the string.
3379      The <replaceable>flags</> parameter is an optional text string containing
3380      zero or more single-letter flags that change the function's behavior.
3381      <function>regexp_split_to_table</function> supports the flags described in
3382      <xref linkend="posix-embedded-options-table">.
3383     </para>
3384
3385     <para>
3386      The <function>regexp_split_to_array</> function behaves the same as
3387      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
3388      returns its result as an array of <type>text</>.  It has the syntax
3389      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
3390      <optional>, <replaceable>flags</> </optional>).
3391      The parameters are the same as for <function>regexp_split_to_table</>.
3392     </para>
3393
3394    <para>
3395     Some examples:
3396 <programlisting>
3397
3398 SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\\s+') AS foo;
3399   foo   
3400 --------
3401  the    
3402  quick  
3403  brown  
3404  fox    
3405  jumped 
3406  over   
3407  the    
3408  lazy   
3409  dog    
3410 (9 rows)
3411
3412 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
3413               regexp_split_to_array             
3414 ------------------------------------------------
3415  {the,quick,brown,fox,jumped,over,the,lazy,dog}
3416 (1 row)
3417
3418 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
3419  foo 
3420 -----
3421  t         
3422  h         
3423  e         
3424  q         
3425  u         
3426  i         
3427  c         
3428  k         
3429  b         
3430  r         
3431  o         
3432  w         
3433  n         
3434  f         
3435  o         
3436  x         
3437 (16 rows)
3438 </programlisting>
3439    </para>
3440
3441    <para>
3442     As the last example demonstrates, the regexp split functions ignore
3443     zero-length matches that occur at the start or end of the string
3444     or immediately after a previous match.  This is contrary to the strict
3445     definition of regexp matching that is implemented by
3446     <function>regexp_matches</>, but is usually the most convenient behavior
3447     in practice.  Other software systems such as Perl use similar definitions.
3448    </para>
3449
3450 <!-- derived from the re_syntax.n man page -->
3451
3452    <sect3 id="posix-syntax-details">
3453     <title>Regular Expression Details</title>
3454
3455    <para>
3456     <productname>PostgreSQL</productname>'s regular expressions are implemented
3457     using a package written by Henry Spencer.  Much of
3458     the description of regular expressions below is copied verbatim from his
3459     manual entry.
3460    </para>
3461
3462    <para>
3463     Regular expressions (<acronym>RE</acronym>s), as defined in
3464     <acronym>POSIX</acronym> 1003.2, come in two forms:
3465     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
3466     (roughly those of <command>egrep</command>), and
3467     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
3468     (roughly those of <command>ed</command>).
3469     <productname>PostgreSQL</productname> supports both forms, and
3470     also implements some extensions
3471     that are not in the POSIX standard, but have become widely used anyway
3472     due to their availability in programming languages such as Perl and Tcl.
3473     <acronym>RE</acronym>s using these non-POSIX extensions are called
3474     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
3475     in this documentation.  AREs are almost an exact superset of EREs,
3476     but BREs have several notational incompatibilities (as well as being
3477     much more limited).
3478     We first describe the ARE and ERE forms, noting features that apply
3479     only to AREs, and then describe how BREs differ.
3480    </para>
3481
3482    <note>
3483     <para>
3484      The form of regular expressions accepted by
3485      <productname>PostgreSQL</> can be chosen by setting the <xref
3486      linkend="guc-regex-flavor"> run-time parameter.  The usual
3487      setting is <literal>advanced</>, but one might choose
3488      <literal>extended</> for maximum backwards compatibility with
3489      pre-7.4 releases of <productname>PostgreSQL</>.
3490     </para>
3491    </note>
3492
3493    <para>
3494     A regular expression is defined as one or more
3495     <firstterm>branches</firstterm>, separated by
3496     <literal>|</literal>.  It matches anything that matches one of the
3497     branches.
3498    </para>
3499
3500    <para>
3501     A branch is zero or more <firstterm>quantified atoms</> or
3502     <firstterm>constraints</>, concatenated.
3503     It matches a match for the first, followed by a match for the second, etc;
3504     an empty branch matches the empty string.
3505    </para>
3506
3507    <para>
3508     A quantified atom is an <firstterm>atom</> possibly followed
3509     by a single <firstterm>quantifier</>.
3510     Without a quantifier, it matches a match for the atom.
3511     With a quantifier, it can match some number of matches of the atom.
3512     An <firstterm>atom</firstterm> can be any of the possibilities
3513     shown in <xref linkend="posix-atoms-table">.
3514     The possible quantifiers and their meanings are shown in
3515     <xref linkend="posix-quantifiers-table">.
3516    </para>
3517
3518    <para>
3519     A <firstterm>constraint</> matches an empty string, but matches only when
3520     specific conditions are met.  A constraint can be used where an atom
3521     could be used, except it cannot be followed by a quantifier.
3522     The simple constraints are shown in
3523     <xref linkend="posix-constraints-table">;
3524     some more constraints are described later.
3525    </para>
3526
3527
3528    <table id="posix-atoms-table">
3529     <title>Regular Expression Atoms</title>
3530
3531     <tgroup cols="2">
3532      <thead>
3533       <row>
3534        <entry>Atom</entry>
3535        <entry>Description</entry>
3536       </row>
3537      </thead>
3538
3539       <tbody>
3540        <row>
3541        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3542        <entry> (where <replaceable>re</> is any regular expression)
3543        matches a match for
3544        <replaceable>re</>, with the match noted for possible reporting </entry>
3545        </row>
3546
3547        <row>
3548        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3549        <entry> as above, but the match is not noted for reporting
3550        (a <quote>non-capturing</> set of parentheses)
3551        (AREs only) </entry>
3552        </row>
3553
3554        <row>
3555        <entry> <literal>.</> </entry>
3556        <entry> matches any single character </entry>
3557        </row>
3558
3559        <row>
3560        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
3561        <entry> a <firstterm>bracket expression</>,
3562        matching any one of the <replaceable>chars</> (see
3563        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
3564        </row>
3565
3566        <row>
3567        <entry> <literal>\</><replaceable>k</> </entry>
3568        <entry> (where <replaceable>k</> is a non-alphanumeric character)
3569        matches that character taken as an ordinary character,
3570        e.g. <literal>\\</> matches a backslash character </entry>
3571        </row>
3572
3573        <row>
3574        <entry> <literal>\</><replaceable>c</> </entry>
3575        <entry> where <replaceable>c</> is alphanumeric
3576        (possibly followed by other characters)
3577        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
3578        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
3579        </row>
3580
3581        <row>
3582        <entry> <literal>{</> </entry>
3583        <entry> when followed by a character other than a digit,
3584        matches the left-brace character <literal>{</>;
3585        when followed by a digit, it is the beginning of a
3586        <replaceable>bound</> (see below) </entry>
3587        </row>
3588
3589        <row>
3590        <entry> <replaceable>x</> </entry>
3591        <entry> where <replaceable>x</> is a single character with no other
3592        significance, matches that character </entry>
3593        </row>
3594       </tbody>
3595      </tgroup>
3596     </table>
3597
3598    <para>
3599     An RE cannot end with <literal>\</>.
3600    </para>
3601
3602    <note>
3603     <para>
3604      Remember that the backslash (<literal>\</literal>) already has a special
3605      meaning in <productname>PostgreSQL</> string literals.
3606      To write a pattern constant that contains a backslash,
3607      you must write two backslashes in the statement, assuming escape
3608      string syntax is used (see <xref linkend="sql-syntax-strings">).
3609     </para>
3610    </note>
3611
3612    <table id="posix-quantifiers-table">
3613     <title>Regular Expression Quantifiers</title>
3614
3615     <tgroup cols="2">
3616      <thead>
3617       <row>
3618        <entry>Quantifier</entry>
3619        <entry>Matches</entry>
3620       </row>
3621      </thead>
3622
3623       <tbody>
3624        <row>
3625        <entry> <literal>*</> </entry>
3626        <entry> a sequence of 0 or more matches of the atom </entry>
3627        </row>
3628
3629        <row>
3630        <entry> <literal>+</> </entry>
3631        <entry> a sequence of 1 or more matches of the atom </entry>
3632        </row>
3633
3634        <row>
3635        <entry> <literal>?</> </entry>
3636        <entry> a sequence of 0 or 1 matches of the atom </entry>
3637        </row>
3638
3639        <row>
3640        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
3641        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
3642        </row>
3643
3644        <row>
3645        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
3646        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
3647        </row>
3648
3649        <row>
3650        <entry>
3651        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3652        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
3653        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
3654        <replaceable>n</> </entry>
3655        </row>
3656
3657        <row>
3658        <entry> <literal>*?</> </entry>
3659        <entry> non-greedy version of <literal>*</> </entry>
3660        </row>
3661
3662        <row>
3663        <entry> <literal>+?</> </entry>
3664        <entry> non-greedy version of <literal>+</> </entry>
3665        </row>
3666
3667        <row>
3668        <entry> <literal>??</> </entry>
3669        <entry> non-greedy version of <literal>?</> </entry>
3670        </row>
3671
3672        <row>
3673        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
3674        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
3675        </row>
3676
3677        <row>
3678        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
3679        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
3680        </row>
3681
3682        <row>
3683        <entry>
3684        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
3685        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3686        </row>
3687       </tbody>
3688      </tgroup>
3689     </table>
3690
3691    <para>
3692     The forms using <literal>{</><replaceable>...</><literal>}</>
3693     are known as <firstterm>bounds</>.
3694     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
3695     unsigned decimal integers with permissible values from 0 to 255 inclusive.
3696    </para>
3697
3698     <para>
3699      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
3700      same possibilities as their corresponding normal (<firstterm>greedy</>)
3701      counterparts, but prefer the smallest number rather than the largest
3702      number of matches.
3703      See <xref linkend="posix-matching-rules"> for more detail.
3704    </para>
3705
3706    <note>
3707     <para>
3708      A quantifier cannot immediately follow another quantifier.
3709      A quantifier cannot
3710      begin an expression or subexpression or follow
3711      <literal>^</literal> or <literal>|</literal>.
3712     </para>
3713    </note>
3714
3715    <table id="posix-constraints-table">
3716     <title>Regular Expression Constraints</title>
3717
3718     <tgroup cols="2">
3719      <thead>
3720       <row>
3721        <entry>Constraint</entry>
3722        <entry>Description</entry>
3723       </row>
3724      </thead>
3725
3726       <tbody>
3727        <row>
3728        <entry> <literal>^</> </entry>
3729        <entry> matches at the beginning of the string </entry>
3730        </row>
3731
3732        <row>
3733        <entry> <literal>$</> </entry>
3734        <entry> matches at the end of the string </entry>
3735        </row>
3736
3737        <row>
3738        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
3739        <entry> <firstterm>positive lookahead</> matches at any point
3740        where a substring matching <replaceable>re</> begins
3741        (AREs only) </entry>
3742        </row>
3743
3744        <row>
3745        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
3746        <entry> <firstterm>negative lookahead</> matches at any point
3747        where no substring matching <replaceable>re</> begins
3748        (AREs only) </entry>
3749        </row>
3750       </tbody>
3751      </tgroup>
3752     </table>
3753
3754    <para>
3755     Lookahead constraints cannot contain <firstterm>back references</>
3756     (see <xref linkend="posix-escape-sequences">),
3757     and all parentheses within them are considered non-capturing.
3758    </para>
3759    </sect3>
3760
3761    <sect3 id="posix-bracket-expressions">
3762     <title>Bracket Expressions</title>
3763
3764    <para>
3765     A <firstterm>bracket expression</firstterm> is a list of
3766     characters enclosed in <literal>[]</literal>.  It normally matches
3767     any single character from the list (but see below).  If the list
3768     begins with <literal>^</literal>, it matches any single character
3769     <emphasis>not</> from the rest of the list.
3770     If two characters
3771     in the list are separated by <literal>-</literal>, this is
3772     shorthand for the full range of characters between those two
3773     (inclusive) in the collating sequence,
3774     e.g. <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
3775     any decimal digit.  It is illegal for two ranges to share an
3776     endpoint, e.g.  <literal>a-c-e</literal>.  Ranges are very
3777     collating-sequence-dependent, so portable programs should avoid
3778     relying on them.
3779    </para>
3780
3781    <para>
3782     To include a literal <literal>]</literal> in the list, make it the
3783     first character (following a possible <literal>^</literal>).  To
3784     include a literal <literal>-</literal>, make it the first or last
3785     character, or the second endpoint of a range.  To use a literal
3786     <literal>-</literal> as the first endpoint of a range, enclose it
3787     in <literal>[.</literal> and <literal>.]</literal> to make it a
3788     collating element (see below).  With the exception of these characters,
3789     some combinations using <literal>[</literal>
3790     (see next paragraphs), and escapes (AREs only), all other special
3791     characters lose their special significance within a bracket expression.
3792     In particular, <literal>\</literal> is not special when following
3793     ERE or BRE rules, though it is special (as introducing an escape)
3794     in AREs.
3795    </para>
3796
3797    <para>
3798     Within a bracket expression, a collating element (a character, a
3799     multiple-character sequence that collates as if it were a single
3800     character, or a collating-sequence name for either) enclosed in
3801     <literal>[.</literal> and <literal>.]</literal> stands for the
3802     sequence of characters of that collating element.  The sequence is
3803     a single element of the bracket expression's list.  A bracket
3804     expression containing a multiple-character collating element can thus
3805     match more than one character, e.g. if the collating sequence
3806     includes a <literal>ch</literal> collating element, then the RE
3807     <literal>[[.ch.]]*c</literal> matches the first five characters of
3808     <literal>chchcc</literal>.
3809    </para>
3810
3811    <note>
3812     <para>
3813      <productname>PostgreSQL</> currently has no multicharacter collating
3814      elements. This information describes possible future behavior.
3815     </para>
3816    </note>
3817
3818    <para>
3819     Within a bracket expression, a collating element enclosed in
3820     <literal>[=</literal> and <literal>=]</literal> is an equivalence
3821     class, standing for the sequences of characters of all collating
3822     elements equivalent to that one, including itself.  (If there are
3823     no other equivalent collating elements, the treatment is as if the
3824     enclosing delimiters were <literal>[.</literal> and
3825     <literal>.]</literal>.)  For example, if <literal>o</literal> and
3826     <literal>^</literal> are the members of an equivalence class, then
3827     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
3828     <literal>[o^]</literal> are all synonymous.  An equivalence class
3829     cannot be an endpoint of a range.
3830    </para>
3831
3832    <para>
3833     Within a bracket expression, the name of a character class
3834     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
3835     for the list of all characters belonging to that class.  Standard
3836     character class names are: <literal>alnum</literal>,
3837     <literal>alpha</literal>, <literal>blank</literal>,
3838     <literal>cntrl</literal>, <literal>digit</literal>,
3839     <literal>graph</literal>, <literal>lower</literal>,
3840     <literal>print</literal>, <literal>punct</literal>,
3841     <literal>space</literal>, <literal>upper</literal>,
3842     <literal>xdigit</literal>.  These stand for the character classes
3843     defined in
3844     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
3845     A locale can provide others.  A character class cannot be used as
3846     an endpoint of a range.
3847    </para>
3848
3849    <para>
3850     There are two special cases of bracket expressions:  the bracket
3851     expressions <literal>[[:&lt;:]]</literal> and
3852     <literal>[[:&gt;:]]</literal> are constraints,
3853     matching empty strings at the beginning
3854     and end of a word respectively.  A word is defined as a sequence
3855     of word characters that is neither preceded nor followed by word
3856     characters.  A word character is an <literal>alnum</> character (as
3857     defined by
3858     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
3859     or an underscore.  This is an extension, compatible with but not
3860     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
3861     caution in software intended to be portable to other systems.
3862     The constraint escapes described below are usually preferable (they
3863     are no more standard, but are certainly easier to type).
3864    </para>
3865    </sect3>
3866
3867    <sect3 id="posix-escape-sequences">
3868     <title>Regular Expression Escapes</title>
3869
3870    <para>
3871     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
3872     followed by an alphanumeric character. Escapes come in several varieties:
3873     character entry, class shorthands, constraint escapes, and back references.
3874     A <literal>\</> followed by an alphanumeric character but not constituting
3875     a valid escape is illegal in AREs.
3876     In EREs, there are no escapes: outside a bracket expression,
3877     a <literal>\</> followed by an alphanumeric character merely stands for
3878     that character as an ordinary character, and inside a bracket expression,
3879     <literal>\</> is an ordinary character.
3880     (The latter is the one actual incompatibility between EREs and AREs.)
3881    </para>
3882
3883    <para>
3884     <firstterm>Character-entry escapes</> exist to make it easier to specify
3885     non-printing and otherwise inconvenient characters in REs.  They are
3886     shown in <xref linkend="posix-character-entry-escapes-table">.
3887    </para>
3888
3889    <para>
3890     <firstterm>Class-shorthand escapes</> provide shorthands for certain
3891     commonly-used character classes.  They are
3892     shown in <xref linkend="posix-class-shorthand-escapes-table">.
3893    </para>
3894
3895    <para>
3896     A <firstterm>constraint escape</> is a constraint,
3897     matching the empty string if specific conditions are met,
3898     written as an escape.  They are
3899     shown in <xref linkend="posix-constraint-escapes-table">.
3900    </para>
3901
3902    <para>
3903     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
3904     same string matched by the previous parenthesized subexpression specified
3905     by the number <replaceable>n</>
3906     (see <xref linkend="posix-constraint-backref-table">).  For example,
3907     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
3908     but not <literal>bc</> or <literal>cb</>.
3909     The subexpression must entirely precede the back reference in the RE.
3910     Subexpressions are numbered in the order of their leading parentheses.
3911     Non-capturing parentheses do not define subexpressions.
3912    </para>
3913
3914    <note>
3915     <para>
3916      Keep in mind that an escape's leading <literal>\</> will need to be
3917      doubled when entering the pattern as an SQL string constant.  For example:
3918 <programlisting>
3919 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
3920 </programlisting>
3921     </para>
3922    </note>
3923
3924    <table id="posix-character-entry-escapes-table">
3925     <title>Regular Expression Character-Entry Escapes</title>
3926
3927     <tgroup cols="2">
3928      <thead>
3929       <row>
3930        <entry>Escape</entry>
3931        <entry>Description</entry>
3932       </row>
3933      </thead>
3934
3935       <tbody>
3936        <row>
3937        <entry> <literal>\a</> </entry>
3938        <entry> alert (bell) character, as in C </entry>
3939        </row>
3940
3941        <row>
3942        <entry> <literal>\b</> </entry>
3943        <entry> backspace, as in C </entry>
3944        </row>
3945
3946        <row>
3947        <entry> <literal>\B</> </entry>
3948        <entry> synonym for <literal>\</> to help reduce the need for backslash
3949        doubling </entry>
3950        </row>
3951
3952        <row>
3953        <entry> <literal>\c</><replaceable>X</> </entry>
3954        <entry> (where <replaceable>X</> is any character) the character whose
3955        low-order 5 bits are the same as those of
3956        <replaceable>X</>, and whose other bits are all zero </entry>
3957        </row>
3958
3959        <row>
3960        <entry> <literal>\e</> </entry>
3961        <entry> the character whose collating-sequence name
3962        is <literal>ESC</>,
3963        or failing that, the character with octal value 033 </entry>
3964        </row>
3965
3966        <row>
3967        <entry> <literal>\f</> </entry>
3968        <entry> form feed, as in C </entry>
3969        </row>
3970
3971        <row>
3972        <entry> <literal>\n</> </entry>
3973        <entry> newline, as in C </entry>
3974        </row>
3975
3976        <row>
3977        <entry> <literal>\r</> </entry>
3978        <entry> carriage return, as in C </entry>
3979        </row>
3980
3981        <row>
3982        <entry> <literal>\t</> </entry>
3983        <entry> horizontal tab, as in C </entry>
3984        </row>
3985
3986        <row>
3987        <entry> <literal>\u</><replaceable>wxyz</> </entry>
3988        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
3989        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
3990        in the local byte ordering </entry>
3991        </row>
3992
3993        <row>
3994        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
3995        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
3996        digits)
3997        reserved for a somewhat-hypothetical Unicode extension to 32 bits
3998        </entry> 
3999        </row>
4000
4001        <row>
4002        <entry> <literal>\v</> </entry>
4003        <entry> vertical tab, as in C </entry>
4004        </row>
4005
4006        <row>
4007        <entry> <literal>\x</><replaceable>hhh</> </entry>
4008        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4009        digits)
4010        the character whose hexadecimal value is
4011        <literal>0x</><replaceable>hhh</>
4012        (a single character no matter how many hexadecimal digits are used)
4013        </entry>
4014        </row>
4015
4016        <row>
4017        <entry> <literal>\0</> </entry>
4018        <entry> the character whose value is <literal>0</> </entry>
4019        </row>
4020
4021        <row>
4022        <entry> <literal>\</><replaceable>xy</> </entry>
4023        <entry> (where <replaceable>xy</> is exactly two octal digits,
4024        and is not a <firstterm>back reference</>)
4025        the character whose octal value is
4026        <literal>0</><replaceable>xy</> </entry>
4027        </row>
4028
4029        <row>
4030        <entry> <literal>\</><replaceable>xyz</> </entry>
4031        <entry> (where <replaceable>xyz</> is exactly three octal digits,
4032        and is not a <firstterm>back reference</>)
4033        the character whose octal value is
4034        <literal>0</><replaceable>xyz</> </entry>
4035        </row>
4036       </tbody>
4037      </tgroup>
4038     </table>
4039
4040    <para>
4041     Hexadecimal digits are <literal>0</>-<literal>9</>,
4042     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4043     Octal digits are <literal>0</>-<literal>7</>.
4044    </para>
4045
4046    <para>
4047     The character-entry escapes are always taken as ordinary characters.
4048     For example, <literal>\135</> is <literal>]</> in ASCII, but
4049     <literal>\135</> does not terminate a bracket expression.
4050    </para>
4051
4052    <table id="posix-class-shorthand-escapes-table">
4053     <title>Regular Expression Class-Shorthand Escapes</title>
4054
4055     <tgroup cols="2">
4056      <thead>
4057       <row>
4058        <entry>Escape</entry>
4059        <entry>Description</entry>
4060       </row>
4061      </thead>
4062
4063       <tbody>
4064        <row>
4065        <entry> <literal>\d</> </entry>
4066        <entry> <literal>[[:digit:]]</> </entry>
4067        </row>
4068
4069        <row>
4070        <entry> <literal>\s</> </entry>
4071        <entry> <literal>[[:space:]]</> </entry>
4072        </row>
4073
4074        <row>
4075        <entry> <literal>\w</> </entry>
4076        <entry> <literal>[[:alnum:]_]</>
4077        (note underscore is included) </entry>
4078        </row>
4079
4080        <row>
4081        <entry> <literal>\D</> </entry>
4082        <entry> <literal>[^[:digit:]]</> </entry>
4083        </row>
4084
4085        <row>
4086        <entry> <literal>\S</> </entry>
4087        <entry> <literal>[^[:space:]]</> </entry>
4088        </row>
4089
4090        <row>
4091        <entry> <literal>\W</> </entry>
4092        <entry> <literal>[^[:alnum:]_]</>
4093        (note underscore is included) </entry>
4094        </row>
4095       </tbody>
4096      </tgroup>
4097     </table>
4098
4099    <para>
4100     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4101     and <literal>\w</> lose their outer brackets,
4102     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4103     (So, for example, <literal>[a-c\d]</> is equivalent to
4104     <literal>[a-c[:digit:]]</>.
4105     Also, <literal>[a-c\D]</>, which is equivalent to
4106     <literal>[a-c^[:digit:]]</>, is illegal.)
4107    </para>
4108
4109    <table id="posix-constraint-escapes-table">
4110     <title>Regular Expression Constraint Escapes</title>
4111
4112     <tgroup cols="2">
4113      <thead>
4114       <row>
4115        <entry>Escape</entry>
4116        <entry>Description</entry>
4117       </row>
4118      </thead>
4119
4120       <tbody>
4121        <row>
4122        <entry> <literal>\A</> </entry>
4123        <entry> matches only at the beginning of the string
4124        (see <xref linkend="posix-matching-rules"> for how this differs from
4125        <literal>^</>) </entry>
4126        </row>
4127
4128        <row>
4129        <entry> <literal>\m</> </entry>
4130        <entry> matches only at the beginning of a word </entry>
4131        </row>
4132
4133        <row>
4134        <entry> <literal>\M</> </entry>
4135        <entry> matches only at the end of a word </entry>
4136        </row>
4137
4138        <row>
4139        <entry> <literal>\y</> </entry>
4140        <entry> matches only at the beginning or end of a word </entry>
4141        </row>
4142
4143        <row>
4144        <entry> <literal>\Y</> </entry>
4145        <entry> matches only at a point that is not the beginning or end of a
4146        word </entry>
4147        </row>
4148
4149        <row>
4150        <entry> <literal>\Z</> </entry>
4151        <entry> matches only at the end of the string
4152        (see <xref linkend="posix-matching-rules"> for how this differs from
4153        <literal>$</>) </entry>
4154        </row>
4155       </tbody>
4156      </tgroup>
4157     </table>
4158
4159    <para>
4160     A word is defined as in the specification of
4161     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4162     Constraint escapes are illegal within bracket expressions.
4163    </para>
4164
4165    <table id="posix-constraint-backref-table">
4166     <title>Regular Expression Back References</title>
4167
4168     <tgroup cols="2">
4169      <thead>
4170       <row>
4171        <entry>Escape</entry>
4172        <entry>Description</entry>
4173       </row>
4174      </thead>
4175
4176       <tbody>
4177        <row>
4178        <entry> <literal>\</><replaceable>m</> </entry>
4179        <entry> (where <replaceable>m</> is a nonzero digit)
4180        a back reference to the <replaceable>m</>'th subexpression </entry>
4181        </row>
4182
4183        <row>
4184        <entry> <literal>\</><replaceable>mnn</> </entry>
4185        <entry> (where <replaceable>m</> is a nonzero digit, and
4186        <replaceable>nn</> is some more digits, and the decimal value
4187        <replaceable>mnn</> is not greater than the number of closing capturing
4188        parentheses seen so far) 
4189        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4190        </row>
4191       </tbody>
4192      </tgroup>
4193     </table>
4194
4195    <note>
4196     <para>
4197      There is an inherent historical ambiguity between octal character-entry 
4198      escapes and back references, which is resolved by heuristics,
4199      as hinted at above.
4200      A leading zero always indicates an octal escape.
4201      A single non-zero digit, not followed by another digit,
4202      is always taken as a back reference.
4203      A multidigit sequence not starting with a zero is taken as a back 
4204      reference if it comes after a suitable subexpression
4205      (i.e. the number is in the legal range for a back reference),
4206      and otherwise is taken as octal.
4207     </para>
4208    </note>
4209    </sect3>
4210
4211    <sect3 id="posix-metasyntax">
4212     <title>Regular Expression Metasyntax</title>
4213
4214    <para>
4215     In addition to the main syntax described above, there are some special
4216     forms and miscellaneous syntactic facilities available.
4217    </para>
4218
4219    <para>
4220     Normally the flavor of RE being used is determined by
4221     <varname>regex_flavor</>.
4222     However, this can be overridden by a <firstterm>director</> prefix.
4223     If an RE begins with <literal>***:</>,
4224     the rest of the RE is taken as an ARE regardless of
4225     <varname>regex_flavor</>.
4226     If an RE begins with <literal>***=</>,
4227     the rest of the RE is taken to be a literal string,
4228     with all characters considered ordinary characters.
4229    </para>
4230
4231    <para>
4232     An ARE can begin with <firstterm>embedded options</>:
4233     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4234     (where <replaceable>xyz</> is one or more alphabetic characters)
4235     specifies options affecting the rest of the RE.
4236     These options override any previously determined options (including
4237     both the RE flavor and case sensitivity).
4238     The available option letters are
4239     shown in <xref linkend="posix-embedded-options-table">.
4240    </para>
4241
4242    <table id="posix-embedded-options-table">
4243     <title>ARE Embedded-Option Letters</title>
4244
4245     <tgroup cols="2">
4246      <thead>
4247       <row>
4248        <entry>Option</entry>
4249        <entry>Description</entry>
4250       </row>
4251      </thead>
4252
4253       <tbody>
4254        <row>
4255        <entry> <literal>b</> </entry>
4256        <entry> rest of RE is a BRE </entry>
4257        </row>
4258
4259        <row>
4260        <entry> <literal>c</> </entry>
4261        <entry> case-sensitive matching (overrides operator type) </entry>
4262        </row>
4263
4264        <row>
4265        <entry> <literal>e</> </entry>
4266        <entry> rest of RE is an ERE </entry>
4267        </row>
4268
4269        <row>
4270        <entry> <literal>i</> </entry>
4271        <entry> case-insensitive matching (see
4272        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4273        </row>
4274
4275        <row>
4276        <entry> <literal>m</> </entry>
4277        <entry> historical synonym for <literal>n</> </entry>
4278        </row>
4279
4280        <row>
4281        <entry> <literal>n</> </entry>
4282        <entry> newline-sensitive matching (see
4283        <xref linkend="posix-matching-rules">) </entry>
4284        </row>
4285
4286        <row>
4287        <entry> <literal>p</> </entry>
4288        <entry> partial newline-sensitive matching (see
4289        <xref linkend="posix-matching-rules">) </entry>
4290        </row>
4291
4292        <row>
4293        <entry> <literal>q</> </entry>
4294        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4295        characters </entry>
4296        </row>
4297
4298        <row>
4299        <entry> <literal>s</> </entry>
4300        <entry> non-newline-sensitive matching (default) </entry>
4301        </row>
4302
4303        <row>
4304        <entry> <literal>t</> </entry>
4305        <entry> tight syntax (default; see below) </entry>
4306        </row>
4307
4308        <row>
4309        <entry> <literal>w</> </entry>
4310        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4311        (see <xref linkend="posix-matching-rules">) </entry>
4312        </row>
4313
4314        <row>
4315        <entry> <literal>x</> </entry>
4316        <entry> expanded syntax (see below) </entry>
4317        </row>
4318       </tbody>
4319      </tgroup>
4320     </table>
4321
4322    <para>
4323     Embedded options take effect at the <literal>)</> terminating the sequence.
4324     They can appear only at the start of an ARE (after the
4325     <literal>***:</> director if any).
4326    </para>
4327
4328    <para>
4329     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4330     characters are significant, there is an <firstterm>expanded</> syntax,
4331     available by specifying the embedded <literal>x</> option.
4332     In the expanded syntax,
4333     white-space characters in the RE are ignored, as are
4334     all characters between a <literal>#</>
4335     and the following newline (or the end of the RE).  This
4336     permits paragraphing and commenting a complex RE.
4337     There are three exceptions to that basic rule:
4338
4339     <itemizedlist>
4340      <listitem>
4341       <para>
4342        a white-space character or <literal>#</> preceded by <literal>\</> is
4343        retained
4344       </para>
4345      </listitem>
4346      <listitem>
4347       <para>
4348        white space or <literal>#</> within a bracket expression is retained
4349       </para>
4350      </listitem>
4351      <listitem>
4352       <para>
4353        white space and comments cannot appear within multicharacter symbols,
4354        such as <literal>(?:</>
4355       </para>
4356      </listitem>
4357     </itemizedlist>
4358
4359     For this purpose, white-space characters are blank, tab, newline, and
4360     any character that belongs to the <replaceable>space</> character class.
4361    </para>
4362
4363    <para>
4364     Finally, in an ARE, outside bracket expressions, the sequence
4365     <literal>(?#</><replaceable>ttt</><literal>)</>
4366     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4367     is a comment, completely ignored.
4368     Again, this is not allowed between the characters of
4369     multicharacter symbols, like <literal>(?:</>.
4370     Such comments are more a historical artifact than a useful facility,
4371     and their use is deprecated; use the expanded syntax instead.
4372    </para>
4373
4374    <para>
4375     <emphasis>None</> of these metasyntax extensions is available if
4376     an initial <literal>***=</> director
4377     has specified that the user's input be treated as a literal string
4378     rather than as an RE.
4379    </para>
4380    </sect3>
4381
4382    <sect3 id="posix-matching-rules">
4383     <title>Regular Expression Matching Rules</title>
4384
4385    <para>
4386     In the event that an RE could match more than one substring of a given
4387     string, the RE matches the one starting earliest in the string.
4388     If the RE could match more than one substring starting at that point,
4389     either the longest possible match or the shortest possible match will
4390     be taken, depending on whether the RE is <firstterm>greedy</> or
4391     <firstterm>non-greedy</>.
4392    </para>
4393
4394    <para>
4395     Whether an RE is greedy or not is determined by the following rules:
4396     <itemizedlist>
4397      <listitem>
4398       <para>
4399        Most atoms, and all constraints, have no greediness attribute (because
4400        they cannot match variable amounts of text anyway).
4401       </para>
4402      </listitem>
4403      <listitem>
4404       <para>
4405        Adding parentheses around an RE does not change its greediness.
4406       </para>
4407      </listitem>
4408      <listitem>
4409       <para>
4410        A quantified atom with a fixed-repetition quantifier
4411        (<literal>{</><replaceable>m</><literal>}</>
4412        or
4413        <literal>{</><replaceable>m</><literal>}?</>)
4414        has the same greediness (possibly none) as the atom itself.
4415       </para>
4416      </listitem>
4417      <listitem>
4418       <para>
4419        A quantified atom with other normal quantifiers (including
4420        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4421        with <replaceable>m</> equal to <replaceable>n</>)
4422        is greedy (prefers longest match).
4423       </para>
4424      </listitem>
4425      <listitem>
4426       <para>
4427        A quantified atom with a non-greedy quantifier (including
4428        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4429        with <replaceable>m</> equal to <replaceable>n</>)
4430        is non-greedy (prefers shortest match).
4431       </para>
4432      </listitem>
4433      <listitem>
4434       <para>
4435        A branch &mdash; that is, an RE that has no top-level
4436        <literal>|</> operator &mdash; has the same greediness as the first
4437        quantified atom in it that has a greediness attribute.
4438       </para>
4439      </listitem>
4440      <listitem>
4441       <para>
4442        An RE consisting of two or more branches connected by the
4443        <literal>|</> operator is always greedy.
4444       </para>
4445      </listitem>
4446     </itemizedlist>
4447    </para>
4448
4449    <para>
4450     The above rules associate greediness attributes not only with individual
4451     quantified atoms, but with branches and entire REs that contain quantified
4452     atoms.  What that means is that the matching is done in such a way that
4453     the branch, or whole RE, matches the longest or shortest possible
4454     substring <emphasis>as a whole</>.  Once the length of the entire match
4455     is determined, the part of it that matches any particular subexpression
4456     is determined on the basis of the greediness attribute of that
4457     subexpression, with subexpressions starting earlier in the RE taking
4458     priority over ones starting later.
4459    </para>
4460
4461    <para>
4462     An example of what this means:
4463 <screen>
4464 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4465 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4466 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4467 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4468 </screen>
4469     In the first case, the RE as a whole is greedy because <literal>Y*</>
4470     is greedy.  It can match beginning at the <literal>Y</>, and it matches
4471     the longest possible string starting there, i.e., <literal>Y123</>.
4472     The output is the parenthesized part of that, or <literal>123</>.
4473     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4474     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
4475     the shortest possible string starting there, i.e., <literal>Y1</>.
4476     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4477     the decision as to the overall match length; so it is forced to match
4478     just <literal>1</>.
4479    </para>
4480
4481    <para>
4482     In short, when an RE contains both greedy and non-greedy subexpressions,
4483     the total match length is either as long as possible or as short as
4484     possible, according to the attribute assigned to the whole RE.  The
4485     attributes assigned to the subexpressions only affect how much of that
4486     match they are allowed to <quote>eat</> relative to each other.
4487    </para>
4488
4489    <para>
4490     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4491     can be used to force greediness or non-greediness, respectively,
4492     on a subexpression or a whole RE.
4493    </para>
4494
4495    <para>
4496     Match lengths are measured in characters, not collating elements.
4497     An empty string is considered longer than no match at all.
4498     For example:
4499     <literal>bb*</>
4500     matches the three middle characters of <literal>abbbc</>;
4501     <literal>(week|wee)(night|knights)</>
4502     matches all ten characters of <literal>weeknights</>;
4503     when <literal>(.*).*</>
4504     is matched against <literal>abc</> the parenthesized subexpression
4505     matches all three characters; and when
4506     <literal>(a*)*</> is matched against <literal>bc</>
4507     both the whole RE and the parenthesized
4508     subexpression match an empty string.
4509    </para>
4510
4511    <para>
4512     If case-independent matching is specified,
4513     the effect is much as if all case distinctions had vanished from the
4514     alphabet.
4515     When an alphabetic that exists in multiple cases appears as an
4516     ordinary character outside a bracket expression, it is effectively
4517     transformed into a bracket expression containing both cases,
4518     e.g. <literal>x</> becomes <literal>[xX]</>.
4519     When it appears inside a bracket expression, all case counterparts
4520     of it are added to the bracket expression, e.g.
4521     <literal>[x]</> becomes <literal>[xX]</>
4522     and <literal>[^x]</> becomes <literal>[^xX]</>.
4523    </para>
4524
4525    <para>
4526     If newline-sensitive matching is specified, <literal>.</>
4527     and bracket expressions using <literal>^</>
4528     will never match the newline character
4529     (so that matches will never cross newlines unless the RE
4530     explicitly arranges it)
4531     and <literal>^</>and <literal>$</>
4532     will match the empty string after and before a newline
4533     respectively, in addition to matching at beginning and end of string
4534     respectively.
4535     But the ARE escapes <literal>\A</> and <literal>\Z</>
4536     continue to match beginning or end of string <emphasis>only</>.
4537    </para>
4538
4539    <para>
4540     If partial newline-sensitive matching is specified,
4541     this affects <literal>.</> and bracket expressions
4542     as with newline-sensitive matching, but not <literal>^</>
4543     and <literal>$</>.
4544    </para>
4545
4546    <para>
4547     If inverse partial newline-sensitive matching is specified,
4548     this affects <literal>^</> and <literal>$</>
4549     as with newline-sensitive matching, but not <literal>.</>
4550     and bracket expressions.
4551     This isn't very useful but is provided for symmetry.
4552    </para>
4553    </sect3>
4554
4555    <sect3 id="posix-limits-compatibility">
4556     <title>Limits and Compatibility</title>
4557
4558    <para>
4559     No particular limit is imposed on the length of REs in this
4560     implementation.  However,
4561     programs intended to be highly portable should not employ REs longer
4562     than 256 bytes,
4563     as a POSIX-compliant implementation can refuse to accept such REs.
4564    </para>
4565
4566    <para>
4567     The only feature of AREs that is actually incompatible with
4568     POSIX EREs is that <literal>\</> does not lose its special
4569     significance inside bracket expressions.
4570     All other ARE features use syntax which is illegal or has
4571     undefined or unspecified effects in POSIX EREs;
4572     the <literal>***</> syntax of directors likewise is outside the POSIX
4573     syntax for both BREs and EREs.
4574    </para>
4575
4576    <para>
4577     Many of the ARE extensions are borrowed from Perl, but some have
4578     been changed to clean them up, and a few Perl extensions are not present.
4579     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
4580     the lack of special treatment for a trailing newline,
4581     the addition of complemented bracket expressions to the things
4582     affected by newline-sensitive matching,
4583     the restrictions on parentheses and back references in lookahead
4584     constraints, and the longest/shortest-match (rather than first-match)
4585     matching semantics.
4586    </para>
4587
4588    <para>
4589     Two significant incompatibilities exist between AREs and the ERE syntax
4590     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
4591
4592     <itemizedlist>
4593      <listitem>
4594       <para>
4595        In AREs, <literal>\</> followed by an alphanumeric character is either
4596        an escape or an error, while in previous releases, it was just another
4597        way of writing the alphanumeric.
4598        This should not be much of a problem because there was no reason to
4599        write such a sequence in earlier releases.
4600       </para>
4601      </listitem>
4602      <listitem>
4603       <para>
4604        In AREs, <literal>\</> remains a special character within
4605        <literal>[]</>, so a literal <literal>\</> within a bracket
4606        expression must be written <literal>\\</>.
4607       </para>
4608      </listitem>
4609     </itemizedlist>
4610
4611     While these differences are unlikely to create a problem for most
4612     applications, you can avoid them if necessary by
4613     setting <varname>regex_flavor</> to <literal>extended</>.
4614    </para>
4615    </sect3>
4616
4617    <sect3 id="posix-basic-regexes">
4618     <title>Basic Regular Expressions</title>
4619
4620    <para>
4621     BREs differ from EREs in several respects.
4622     <literal>|</>, <literal>+</>, and <literal>?</>
4623     are ordinary characters and there is no equivalent
4624     for their functionality.
4625     The delimiters for bounds are
4626     <literal>\{</> and <literal>\}</>,
4627     with <literal>{</> and <literal>}</>
4628     by themselves ordinary characters.
4629     The parentheses for nested subexpressions are
4630     <literal>\(</> and <literal>\)</>,
4631     with <literal>(</> and <literal>)</> by themselves ordinary characters.
4632     <literal>^</> is an ordinary character except at the beginning of the
4633     RE or the beginning of a parenthesized subexpression,
4634     <literal>$</> is an ordinary character except at the end of the
4635     RE or the end of a parenthesized subexpression,
4636     and <literal>*</> is an ordinary character if it appears at the beginning
4637     of the RE or the beginning of a parenthesized subexpression
4638     (after a possible leading <literal>^</>).
4639     Finally, single-digit back references are available, and
4640     <literal>\&lt;</> and <literal>\&gt;</>
4641     are synonyms for
4642     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
4643     respectively; no other escapes are available.
4644    </para>
4645    </sect3>
4646
4647 <!-- end re_syntax.n man page -->
4648
4649   </sect2>
4650  </sect1>
4651
4652
4653   <sect1 id="functions-formatting">
4654    <title>Data Type Formatting Functions</title>
4655
4656    <indexterm>
4657     <primary>formatting</primary>
4658    </indexterm>
4659
4660    <indexterm>
4661     <primary>to_char</primary>
4662    </indexterm>
4663    <indexterm>
4664     <primary>to_date</primary>
4665    </indexterm>
4666    <indexterm>
4667     <primary>to_number</primary>
4668    </indexterm>
4669    <indexterm>
4670     <primary>to_timestamp</primary>
4671    </indexterm>
4672
4673    <para>
4674     The <productname>PostgreSQL</productname> formatting functions
4675     provide a powerful set of tools for converting various data types
4676     (date/time, integer, floating point, numeric) to formatted strings
4677     and for converting from formatted strings to specific data types.
4678     <xref linkend="functions-formatting-table"> lists them.
4679     These functions all follow a common calling convention: the first
4680     argument is the value to be formatted and the second argument is a
4681     template that defines the output or input format.
4682    </para>
4683    <para>
4684     The <function>to_timestamp</function> function can also take a single 
4685     <type>double precision</type> argument to convert from Unix epoch to 
4686     <type>timestamp with time zone</type>.
4687     (<type>Integer</type> Unix epochs are implicitly cast to 
4688     <type>double precision</type>.)
4689    </para>
4690
4691     <table id="functions-formatting-table">
4692      <title>Formatting Functions</title>
4693      <tgroup cols="4">
4694       <thead>
4695        <row>
4696         <entry>Function</entry>
4697         <entry>Return Type</entry>
4698         <entry>Description</entry>
4699         <entry>Example</entry>
4700        </row>
4701       </thead>
4702       <tbody>
4703        <row>
4704         <entry><literal><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</literal></entry>
4705         <entry><type>text</type></entry>
4706         <entry>convert time stamp to string</entry>
4707         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
4708        </row>
4709        <row>
4710         <entry><literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal></entry>
4711         <entry><type>text</type></entry>
4712         <entry>convert interval to string</entry>
4713         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
4714        </row>
4715        <row>
4716         <entry><literal><function>to_char</function>(<type>int</type>, <type>text</type>)</literal></entry>
4717         <entry><type>text</type></entry>
4718         <entry>convert integer to string</entry>
4719         <entry><literal>to_char(125, '999')</literal></entry>
4720        </row>
4721        <row>
4722         <entry><literal><function>to_char</function>(<type>double precision</type>,
4723         <type>text</type>)</literal></entry>
4724         <entry><type>text</type></entry>
4725         <entry>convert real/double precision to string</entry>
4726         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
4727        </row>
4728        <row>
4729         <entry><literal><function>to_char</function>(<type>numeric</type>, <type>text</type>)</literal></entry>
4730         <entry><type>text</type></entry>
4731         <entry>convert numeric to string</entry>
4732         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
4733        </row>
4734        <row>
4735         <entry><literal><function>to_date</function>(<type>text</type>, <type>text</type>)</literal></entry>
4736         <entry><type>date</type></entry>
4737         <entry>convert string to date</entry>
4738         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4739        </row>
4740        <row>
4741         <entry><literal><function>to_number</function>(<type>text</type>, <type>text</type>)</literal></entry>
4742         <entry><type>numeric</type></entry>
4743         <entry>convert string to numeric</entry>
4744         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
4745        </row>
4746        <row>
4747         <entry><literal><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</literal></entry>
4748         <entry><type>timestamp with time zone</type></entry>
4749         <entry>convert string to time stamp</entry>
4750         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4751        </row>
4752        <row>
4753         <entry><literal><function>to_timestamp</function>(<type>double precision</type>)</literal></entry>
4754         <entry><type>timestamp with time zone</type></entry>
4755         <entry>convert UNIX epoch to time stamp</entry>
4756         <entry><literal>to_timestamp(200120400)</literal></entry>
4757        </row>
4758       </tbody>
4759      </tgroup>
4760     </table>
4761
4762    <para>
4763     In an output template string (for <function>to_char</>), there are certain patterns that are
4764     recognized and replaced with appropriately-formatted data from the value
4765     to be formatted.  Any text that is not a template pattern is simply
4766     copied verbatim.  Similarly, in an input template string (for anything but <function>to_char</>), template patterns
4767     identify the parts of the input data string to be looked at and the
4768     values to be found there.
4769    </para>
4770
4771   <para>
4772    <xref linkend="functions-formatting-datetime-table"> shows the
4773    template patterns available for formatting date and time values.
4774   </para>
4775
4776     <table id="functions-formatting-datetime-table">
4777      <title>Template Patterns for Date/Time Formatting</title>
4778      <tgroup cols="2">
4779       <thead>
4780        <row>
4781         <entry>Pattern</entry>
4782         <entry>Description</entry>
4783        </row>
4784       </thead>
4785       <tbody>
4786        <row>
4787         <entry><literal>HH</literal></entry>
4788         <entry>hour of day (01-12)</entry>
4789        </row>
4790        <row>
4791         <entry><literal>HH12</literal></entry>
4792         <entry>hour of day (01-12)</entry>
4793        </row>       
4794        <row>
4795         <entry><literal>HH24</literal></entry>
4796         <entry>hour of day (00-23)</entry>
4797        </row>       
4798        <row>
4799         <entry><literal>MI</literal></entry>
4800         <entry>minute (00-59)</entry>
4801        </row>   
4802        <row>
4803         <entry><literal>SS</literal></entry>
4804         <entry>second (00-59)</entry>
4805        </row>
4806        <row>
4807         <entry><literal>MS</literal></entry>
4808         <entry>millisecond (000-999)</entry>
4809        </row>
4810        <row>
4811         <entry><literal>US</literal></entry>
4812         <entry>microsecond (000000-999999)</entry>
4813        </row>
4814        <row>
4815         <entry><literal>SSSS</literal></entry>
4816         <entry>seconds past midnight (0-86399)</entry>
4817        </row>
4818        <row>
4819         <entry><literal>AM</literal> or <literal>A.M.</literal> or
4820         <literal>PM</literal> or <literal>P.M.</literal></entry>
4821         <entry>meridian indicator (uppercase)</entry>
4822        </row>
4823        <row>
4824         <entry><literal>am</literal> or <literal>a.m.</literal> or
4825         <literal>pm</literal> or <literal>p.m.</literal></entry>
4826         <entry>meridian indicator (lowercase)</entry>
4827        </row>
4828        <row>
4829         <entry><literal>Y,YYY</literal></entry>
4830         <entry>year (4 and more digits) with comma</entry>
4831        </row>
4832        <row>
4833         <entry><literal>YYYY</literal></entry>
4834         <entry>year (4 and more digits)</entry>
4835        </row>
4836        <row>
4837         <entry><literal>YYY</literal></entry>
4838         <entry>last 3 digits of year</entry>
4839        </row>
4840        <row>
4841         <entry><literal>YY</literal></entry>
4842         <entry>last 2 digits of year</entry>
4843        </row>
4844        <row>
4845         <entry><literal>Y</literal></entry>
4846         <entry>last digit of year</entry>
4847        </row>
4848        <row>
4849         <entry><literal>IYYY</literal></entry>
4850         <entry>ISO year (4 and more digits)</entry>
4851        </row>
4852        <row>
4853         <entry><literal>IYY</literal></entry>
4854         <entry>last 3 digits of ISO year</entry>
4855        </row>
4856        <row>
4857         <entry><literal>IY</literal></entry>
4858         <entry>last 2 digits of ISO year</entry>
4859        </row>
4860        <row>
4861         <entry><literal>I</literal></entry>
4862         <entry>last digit of ISO year</entry>
4863        </row>
4864        <row>
4865         <entry><literal>BC</literal> or <literal>B.C.</literal> or
4866         <literal>AD</literal> or <literal>A.D.</literal></entry>
4867         <entry>era indicator (uppercase)</entry>
4868        </row>
4869        <row>
4870         <entry><literal>bc</literal> or <literal>b.c.</literal> or
4871         <literal>ad</literal> or <literal>a.d.</literal></entry>
4872         <entry>era indicator (lowercase)</entry>
4873        </row>
4874        <row>
4875         <entry><literal>MONTH</literal></entry>
4876         <entry>full uppercase month name (blank-padded to 9 chars)</entry>
4877        </row>
4878        <row>
4879         <entry><literal>Month</literal></entry>
4880         <entry>full mixed-case month name (blank-padded to 9 chars)</entry>
4881        </row>
4882        <row>
4883         <entry><literal>month</literal></entry>
4884         <entry>full lowercase month name (blank-padded to 9 chars)</entry>
4885        </row>
4886        <row>
4887         <entry><literal>MON</literal></entry>
4888         <entry>abbreviated uppercase month name (3 chars in English, localized lengths vary)</entry>
4889        </row>
4890        <row>
4891         <entry><literal>Mon</literal></entry>
4892         <entry>abbreviated mixed-case month name (3 chars in English, localized lengths vary)</entry>
4893        </row>
4894        <row>
4895         <entry><literal>mon</literal></entry>
4896         <entry>abbreviated lowercase month name (3 chars in English, localized lengths vary)</entry>
4897        </row>
4898        <row>
4899         <entry><literal>MM</literal></entry>
4900         <entry>month number (01-12)</entry>
4901        </row>
4902        <row>
4903         <entry><literal>DAY</literal></entry>
4904         <entry>full uppercase day name (blank-padded to 9 chars)</entry>
4905        </row>
4906        <row>
4907         <entry><literal>Day</literal></entry>
4908         <entry>full mixed-case day name (blank-padded to 9 chars)</entry>
4909        </row>
4910        <row>
4911         <entry><literal>day</literal></entry>
4912         <entry>full lowercase day name (blank-padded to 9 chars)</entry>
4913        </row>
4914        <row>
4915         <entry><literal>DY</literal></entry>
4916         <entry>abbreviated uppercase day name (3 chars in English, localized lengths vary)</entry>
4917        </row>
4918        <row>
4919         <entry><literal>Dy</literal></entry>
4920         <entry>abbreviated mixed-case day name (3 chars in English, localized lengths vary)</entry>
4921        </row>
4922        <row>
4923         <entry><literal>dy</literal></entry>
4924         <entry>abbreviated lowercase day name (3 chars in English, localized lengths vary)</entry>
4925        </row>
4926        <row>
4927         <entry><literal>DDD</literal></entry>
4928         <entry>day of year (001-366)</entry>
4929        </row>
4930        <row>
4931         <entry><literal>IDDD</literal></entry>
4932         <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
4933        </row>
4934        <row>
4935         <entry><literal>DD</literal></entry>
4936         <entry>day of month (01-31)</entry>
4937        </row>
4938        <row>
4939         <entry><literal>D</literal></entry>
4940         <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
4941        </row>
4942        <row>
4943         <entry><literal>ID</literal></entry>
4944         <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
4945        </row>
4946        <row>
4947         <entry><literal>W</literal></entry>
4948         <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
4949        </row> 
4950        <row>
4951         <entry><literal>WW</literal></entry>
4952         <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
4953        </row>
4954        <row>
4955         <entry><literal>IW</literal></entry>
4956         <entry>ISO week number of year (1 - 53; the first Thursday of the new year is in week 1.)</entry>
4957        </row>
4958        <row>
4959         <entry><literal>CC</literal></entry>
4960         <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
4961        </row>
4962        <row>
4963         <entry><literal>J</literal></entry>
4964         <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
4965        </row>
4966        <row>
4967         <entry><literal>Q</literal></entry>
4968         <entry>quarter</entry>
4969        </row>
4970        <row>
4971         <entry><literal>RM</literal></entry>
4972         <entry>month in Roman numerals (I-XII; I=January) (uppercase)</entry>
4973        </row>
4974        <row>
4975         <entry><literal>rm</literal></entry>
4976         <entry>month in Roman numerals (i-xii; i=January) (lowercase)</entry>
4977        </row>
4978        <row>
4979         <entry><literal>TZ</literal></entry>
4980         <entry>time-zone name (uppercase)</entry>
4981        </row>
4982        <row>
4983         <entry><literal>tz</literal></entry>
4984         <entry>time-zone name (lowercase)</entry>
4985        </row>
4986       </tbody>
4987      </tgroup>
4988     </table>
4989
4990    <para>
4991     Certain modifiers can be applied to any template pattern to alter its
4992     behavior.  For example, <literal>FMMonth</literal>
4993     is the <literal>Month</literal> pattern with the
4994     <literal>FM</literal> modifier.
4995     <xref linkend="functions-formatting-datetimemod-table"> shows the
4996     modifier patterns for date/time formatting.
4997    </para>
4998
4999     <table id="functions-formatting-datetimemod-table">
5000      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5001      <tgroup cols="3">
5002       <thead>
5003        <row>
5004         <entry>Modifier</entry>
5005         <entry>Description</entry>
5006         <entry>Example</entry>
5007        </row>
5008       </thead>
5009       <tbody>
5010        <row>
5011         <entry><literal>FM</literal> prefix</entry>
5012         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5013         <entry><literal>FMMonth</literal></entry>
5014        </row>
5015        <row>
5016         <entry><literal>TH</literal> suffix</entry>
5017         <entry>uppercase ordinal number suffix</entry>
5018         <entry><literal>DDTH</literal></entry>
5019        </row>   
5020        <row>
5021         <entry><literal>th</literal> suffix</entry>
5022         <entry>lowercase ordinal number suffix</entry>
5023         <entry><literal>DDth</literal></entry>
5024        </row>
5025        <row>
5026         <entry><literal>FX</literal> prefix</entry>
5027         <entry>fixed format global option (see usage notes)</entry>
5028         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5029        </row>   
5030        <row>
5031         <entry><literal>TM</literal> prefix</entry>
5032         <entry>translation mode (print localized day and month names based on <varname>lc_messages</>)</entry>
5033         <entry><literal>TMMonth</literal></entry>
5034        </row>       
5035        <row>
5036         <entry><literal>SP</literal> suffix</entry>
5037         <entry>spell mode (not yet implemented)</entry>
5038         <entry><literal>DDSP</literal></entry>
5039        </row>       
5040       </tbody>
5041      </tgroup>
5042     </table>
5043
5044    <para>
5045     Usage notes for date/time formatting:
5046
5047     <itemizedlist>
5048      <listitem>
5049       <para>
5050        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5051        that would otherwise be added to make the output of a pattern be
5052        fixed-width.
5053       </para>
5054      </listitem>
5055
5056      <listitem>
5057       <para>
5058        <literal>TM</literal> does not include trailing blanks.
5059       </para>
5060      </listitem>
5061
5062      <listitem>
5063       <para>
5064        <function>to_timestamp</function> and <function>to_date</function>
5065        skip multiple blank spaces in the input string if the <literal>FX</literal> option 
5066        is not used. <literal>FX</literal> must be specified as the first item
5067        in the template.  For example 
5068        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> is correct, but
5069        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error,
5070        because <function>to_timestamp</function> expects one space only.
5071       </para>
5072      </listitem>
5073
5074      <listitem>
5075       <para>
5076        Ordinary text is allowed in <function>to_char</function>
5077        templates and will be output literally.  You can put a substring
5078        in double quotes to force it to be interpreted as literal text
5079        even if it contains pattern key words.  For example, in
5080        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5081        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5082        will not be.
5083       </para>
5084      </listitem>
5085
5086      <listitem>
5087       <para>
5088        If you want to have a double quote in the output you must
5089        precede it with a backslash, for example <literal>E'\\"YYYY
5090        Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
5091        (Two backslashes are necessary because the backslash already
5092        has a special meaning when using the escape string syntax.)
5093       </para>
5094      </listitem>
5095
5096      <listitem>
5097       <para>
5098        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5099        <type>date</type> has a restriction if you use a year with more than 4 digits. You must
5100        use some non-digit character or template after <literal>YYYY</literal>,
5101        otherwise the year is always interpreted as 4 digits. For example
5102        (with the year 20000):
5103        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
5104        interpreted as a 4-digit year; instead use a non-digit 
5105        separator after the year, like
5106        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5107        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5108       </para>
5109      </listitem>
5110
5111      <listitem>
5112       <para>
5113        In conversions from string to <type>timestamp</type> or
5114        <type>date</type>, the <literal>CC</literal> field is ignored if there
5115        is a <literal>YYY</literal>, <literal>YYYY</literal> or
5116        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5117        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5118        as <literal>(CC-1)*100+YY</literal>.
5119       </para>
5120      </listitem>
5121
5122      <listitem>
5123       <para>
5124        An ISO week date (as distinct from a Gregorian date) can be specified to <function>to_timestamp</function> and <function>to_date</function> in one of two ways:
5125        <itemizedlist>
5126         <listitem>
5127          <para>
5128           Year, week and weekday, for example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal> returns the date <literal>2006-10-19</literal>.  If you omit the weekday it is assumed to be 1 (Monday).
5129          </para>
5130         </listitem>
5131         <listitem>
5132          <para>
5133           Year and day of year, for example <literal>to_date('2006-291', 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5134          </para>
5135         </listitem>
5136        </itemizedlist>
5137       </para>
5138       <para>
5139        Attempting to construct a date using a mixture of ISO week and Gregorian date fields is nonsensical, and could yield unexpected results.  In the context of an ISO year, the concept of a 'month' or 'day of month' has no meaning.  In the context of a Gregorian year, the ISO week has no meaning.  Users should take care to keep Gregorian and ISO date specifications separate.
5140       </para>
5141      </listitem>
5142
5143      <listitem>
5144       <para>
5145        Millisecond (<literal>MS</literal>) and microsecond (<literal>US</literal>)
5146        values in a conversion from string to <type>timestamp</type> are used as part of the
5147        seconds after the decimal point. For example 
5148        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5149        but 300, because the conversion counts it as 12 + 0.3 seconds.
5150        This means for the format <literal>SS:MS</literal>, the input values
5151        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5152        same number of milliseconds. To get three milliseconds, one must use
5153        <literal>12:003</literal>, which the conversion counts as
5154        12 + 0.003 = 12.003 seconds.
5155       </para>
5156
5157       <para>
5158        Here is a more 
5159        complex example: 
5160        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5161        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5162        1230 microseconds = 2.021230 seconds. 
5163       </para>
5164      </listitem>
5165
5166      <listitem>
5167       <para>
5168         <function>to_char(..., 'ID')</function>'s day of the week numbering
5169         matches the <function>extract('isodow', ...)</function> function, but
5170         <function>to_char(..., 'D')</function>'s does not match
5171         <function>extract('dow', ...)</function>'s day numbering.
5172       </para>
5173      </listitem>
5174
5175      <listitem>
5176       <para><function>to_char(interval)</function> formats <literal>HH</> and 
5177         <literal>HH12</> as hours in a single day, while <literal>HH24</>
5178         can output hours exceeding a single day, e.g. &gt;24.
5179       </para>
5180      </listitem>
5181
5182     </itemizedlist>
5183    </para>
5184
5185   <para>
5186    <xref linkend="functions-formatting-numeric-table"> shows the
5187    template patterns available for formatting numeric values.
5188   </para>
5189
5190     <table id="functions-formatting-numeric-table">
5191      <title>Template Patterns for Numeric Formatting</title>
5192      <tgroup cols="2">
5193       <thead>
5194        <row>
5195         <entry>Pattern</entry>
5196         <entry>Description</entry>
5197        </row>
5198       </thead>
5199       <tbody>
5200        <row>
5201         <entry><literal>9</literal></entry>
5202         <entry>value with the specified number of digits</entry>
5203        </row>
5204        <row>
5205         <entry><literal>0</literal></entry>
5206         <entry>value with leading zeros</entry>
5207        </row>
5208        <row>
5209         <entry><literal>.</literal> (period)</entry>
5210         <entry>decimal point</entry>
5211        </row>       
5212        <row>
5213         <entry><literal>,</literal> (comma)</entry>
5214         <entry>group (thousand) separator</entry>
5215        </row>
5216        <row>
5217         <entry><literal>PR</literal></entry>
5218         <entry>negative value in angle brackets</entry>
5219        </row>
5220        <row>
5221         <entry><literal>S</literal></entry>
5222         <entry>sign anchored to number (uses locale)</entry>
5223        </row>
5224        <row>
5225         <entry><literal>L</literal></entry>
5226         <entry>currency symbol (uses locale)</entry>
5227        </row>
5228        <row>
5229         <entry><literal>D</literal></entry>
5230         <entry>decimal point (uses locale)</entry>
5231        </row>
5232        <row>
5233         <entry><literal>G</literal></entry>
5234         <entry>group separator (uses locale)</entry>
5235        </row>
5236        <row>
5237         <entry><literal>MI</literal></entry>
5238         <entry>minus sign in specified position (if number &lt; 0)</entry>
5239        </row>
5240        <row>
5241         <entry><literal>PL</literal></entry>
5242         <entry>plus sign in specified position (if number &gt; 0)</entry>
5243        </row>
5244        <row>
5245         <entry><literal>SG</literal></entry>
5246         <entry>plus/minus sign in specified position</entry>
5247        </row>
5248        <row>
5249         <entry><literal>RN</literal></entry>
5250         <entry>roman numeral (input between 1 and 3999)</entry>
5251        </row>
5252        <row>
5253         <entry><literal>TH</literal> or <literal>th</literal></entry>
5254         <entry>ordinal number suffix</entry>
5255        </row>
5256        <row>
5257         <entry><literal>V</literal></entry>
5258         <entry>shift specified number of digits (see notes)</entry>
5259        </row>
5260        <row>
5261         <entry><literal>EEEE</literal></entry>
5262         <entry>scientific notation (not implemented yet)</entry>
5263        </row>
5264       </tbody>
5265      </tgroup>
5266     </table>
5267
5268    <para>
5269     Usage notes for numeric formatting:
5270
5271     <itemizedlist>
5272      <listitem>
5273       <para>
5274        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5275        <literal>MI</literal> is not anchored to
5276        the number; for example,
5277        <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>,
5278        but <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>.
5279        The Oracle implementation does not allow the use of
5280        <literal>MI</literal> ahead of <literal>9</literal>, but rather
5281        requires that <literal>9</literal> precede
5282        <literal>MI</literal>.
5283       </para>
5284      </listitem>
5285
5286      <listitem>
5287       <para>
5288        <literal>9</literal> results in a value with the same number of 
5289        digits as there are <literal>9</literal>s. If a digit is
5290        not available it outputs a space.
5291       </para>
5292      </listitem>
5293
5294      <listitem>
5295       <para>
5296        <literal>TH</literal> does not convert values less than zero
5297        and does not convert fractional numbers.
5298       </para>
5299      </listitem>
5300
5301      <listitem>
5302       <para>
5303        <literal>PL</literal>, <literal>SG</literal>, and
5304        <literal>TH</literal> are <productname>PostgreSQL</productname>
5305        extensions. 
5306       </para>
5307      </listitem>
5308
5309      <listitem>
5310       <para>
5311        <literal>V</literal> effectively
5312        multiplies the input values by
5313        <literal>10^<replaceable>n</replaceable></literal>, where
5314        <replaceable>n</replaceable> is the number of digits following
5315        <literal>V</literal>. 
5316        <function>to_char</function> does not support the use of
5317        <literal>V</literal> combined with a decimal point.
5318        (E.g., <literal>99.9V99</literal> is not allowed.)
5319       </para>
5320      </listitem>
5321     </itemizedlist>
5322    </para>   
5323
5324    <para>
5325     Certain modifiers can be applied to any template pattern to alter its
5326     behavior.  For example, <literal>FM9999</literal>
5327     is the <literal>9999</literal> pattern with the
5328     <literal>FM</literal> modifier.
5329     <xref linkend="functions-formatting-numericmod-table"> shows the
5330     modifier patterns for numeric formatting.
5331    </para>
5332
5333     <table id="functions-formatting-numericmod-table">
5334      <title>Template Pattern Modifiers for Numeric Formatting</title>
5335      <tgroup cols="3">
5336       <thead>
5337        <row>
5338         <entry>Modifier</entry>
5339         <entry>Description</entry>
5340         <entry>Example</entry>
5341        </row>
5342       </thead>
5343       <tbody>
5344        <row>
5345         <entry><literal>FM</literal> prefix</entry>
5346         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5347         <entry><literal>FM9999</literal></entry>
5348        </row>
5349        <row>
5350         <entry><literal>TH</literal> suffix</entry>
5351         <entry>uppercase ordinal number suffix</entry>
5352         <entry><literal>999TH</literal></entry>
5353        </row>   
5354        <row>
5355         <entry><literal>th</literal> suffix</entry>
5356         <entry>lowercase ordinal number suffix</entry>
5357         <entry><literal>999th</literal></entry>
5358        </row>
5359       </tbody>
5360      </tgroup>
5361     </table>
5362
5363   <para>
5364    <xref linkend="functions-formatting-examples-table"> shows some
5365    examples of the use of the <function>to_char</function> function.
5366   </para>
5367
5368     <table id="functions-formatting-examples-table">
5369      <title><function>to_char</function> Examples</title>
5370      <tgroup cols="2">
5371       <thead>
5372        <row>
5373         <entry>Expression</entry>
5374         <entry>Result</entry>
5375        </row>
5376       </thead>
5377       <tbody>
5378        <row>
5379         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5380         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
5381        </row>
5382        <row>
5383         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5384         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
5385        </row>          
5386        <row>
5387         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5388         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
5389        </row>
5390        <row>
5391         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5392         <entry><literal>'-.1'</literal></entry>
5393        </row>
5394        <row>
5395         <entry><literal>to_char(0.1, '0.9')</literal></entry>
5396         <entry><literal>'&nbsp;0.1'</literal></entry>
5397        </row>
5398        <row>
5399         <entry><literal>to_char(12, '9990999.9')</literal></entry>
5400         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
5401        </row>
5402        <row>
5403         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5404         <entry><literal>'0012.'</literal></entry>
5405        </row>
5406        <row>
5407         <entry><literal>to_char(485, '999')</literal></entry>
5408         <entry><literal>'&nbsp;485'</literal></entry>
5409        </row>
5410        <row>
5411         <entry><literal>to_char(-485, '999')</literal></entry>
5412         <entry><literal>'-485'</literal></entry>
5413        </row>
5414        <row>
5415         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
5416         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
5417        </row>
5418        <row>
5419         <entry><literal>to_char(1485, '9,999')</literal></entry>
5420         <entry><literal>'&nbsp;1,485'</literal></entry>
5421        </row>
5422        <row>
5423         <entry><literal>to_char(1485, '9G999')</literal></entry>
5424         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
5425        </row>
5426        <row>
5427         <entry><literal>to_char(148.5, '999.999')</literal></entry>
5428         <entry><literal>'&nbsp;148.500'</literal></entry>
5429        </row>
5430        <row>
5431         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5432         <entry><literal>'148.5'</literal></entry>
5433        </row>
5434        <row>
5435         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5436         <entry><literal>'148.500'</literal></entry>
5437        </row>
5438        <row>
5439         <entry><literal>to_char(148.5, '999D999')</literal></entry>
5440         <entry><literal>'&nbsp;148,500'</literal></entry>        
5441        </row>
5442        <row>
5443         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5444         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
5445        </row>
5446        <row>
5447         <entry><literal>to_char(-485, '999S')</literal></entry>
5448         <entry><literal>'485-'</literal></entry>
5449        </row>
5450        <row>            
5451         <entry><literal>to_char(-485, '999MI')</literal></entry>
5452         <entry><literal>'485-'</literal></entry>        
5453        </row>
5454        <row>
5455         <entry><literal>to_char(485, '999MI')</literal></entry>
5456         <entry><literal>'485&nbsp;'</literal></entry>           
5457        </row>
5458        <row>
5459         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5460         <entry><literal>'485'</literal></entry>         
5461        </row>
5462        <row>
5463         <entry><literal>to_char(485, 'PL999')</literal></entry>
5464         <entry><literal>'+485'</literal></entry>        
5465        </row>
5466        <row>            
5467         <entry><literal>to_char(485, 'SG999')</literal></entry>
5468         <entry><literal>'+485'</literal></entry>        
5469        </row>
5470        <row>
5471         <entry><literal>to_char(-485, 'SG999')</literal></entry>
5472         <entry><literal>'-485'</literal></entry>        
5473        </row>
5474        <row>
5475         <entry><literal>to_char(-485, '9SG99')</literal></entry>
5476         <entry><literal>'4-85'</literal></entry>        
5477        </row>
5478        <row>
5479         <entry><literal>to_char(-485, '999PR')</literal></entry>
5480         <entry><literal>'&lt;485&gt;'</literal></entry>         
5481        </row>
5482        <row>
5483         <entry><literal>to_char(485, 'L999')</literal></entry>
5484         <entry><literal>'DM&nbsp;485</literal></entry>   
5485        </row>
5486        <row>
5487         <entry><literal>to_char(485, 'RN')</literal></entry>            
5488         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
5489        </row>
5490        <row>
5491         <entry><literal>to_char(485, 'FMRN')</literal></entry>  
5492         <entry><literal>'CDLXXXV'</literal></entry>
5493        </row>
5494        <row>
5495         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5496         <entry><literal>'V'</literal></entry>           
5497        </row>
5498        <row>
5499         <entry><literal>to_char(482, '999th')</literal></entry>
5500         <entry><literal>'&nbsp;482nd'</literal></entry>                         
5501        </row>
5502        <row>
5503         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
5504         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
5505        </row>
5506        <row>
5507         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
5508         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
5509        </row>
5510        <row>
5511         <entry><literal>to_char(12, '99V999')</literal></entry>         
5512         <entry><literal>'&nbsp;12000'</literal></entry>
5513        </row>
5514        <row>
5515         <entry><literal>to_char(12.4, '99V999')</literal></entry>
5516         <entry><literal>'&nbsp;12400'</literal></entry>
5517        </row>
5518        <row>            
5519         <entry><literal>to_char(12.45, '99V9')</literal></entry>
5520         <entry><literal>'&nbsp;125'</literal></entry>
5521        </row>
5522       </tbody>
5523      </tgroup>
5524     </table>
5525
5526   </sect1>
5527
5528
5529   <sect1 id="functions-datetime">
5530    <title>Date/Time Functions and Operators</title>
5531
5532   <para>
5533    <xref linkend="functions-datetime-table"> shows the available
5534    functions for date/time value processing, with details appearing in
5535    the following subsections.  <xref
5536    linkend="operators-datetime-table"> illustrates the behaviors of
5537    the basic arithmetic operators (<literal>+</literal>,
5538    <literal>*</literal>, etc.).  For formatting functions, refer to
5539    <xref linkend="functions-formatting">.  You should be familiar with
5540    the background information on date/time data types from <xref
5541    linkend="datatype-datetime">.
5542   </para>
5543
5544   <para>
5545    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
5546    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
5547    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
5548    For brevity, these variants are not shown separately.  Also, the
5549    <literal>+</> and <literal>*</> operators come in commutative pairs (for
5550    example both date + integer and integer + date); we show only one of each
5551    such pair.
5552   </para>
5553
5554     <table id="operators-datetime-table">
5555      <title>Date/Time Operators</title>
5556
5557      <tgroup cols="3">
5558       <thead>
5559        <row>
5560         <entry>Operator</entry>
5561         <entry>Example</entry>
5562         <entry>Result</entry>
5563        </row>
5564       </thead>
5565
5566       <tbody>
5567        <row>
5568         <entry> <literal>+</literal> </entry>
5569         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
5570         <entry><literal>date '2001-10-05'</literal></entry>
5571        </row>
5572
5573        <row>
5574         <entry> <literal>+</literal> </entry>
5575         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
5576         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
5577        </row>
5578
5579        <row>
5580         <entry> <literal>+</literal> </entry>
5581         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
5582         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
5583        </row>
5584
5585        <row>
5586         <entry> <literal>+</literal> </entry>
5587         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
5588         <entry><literal>interval '1 day 01:00:00'</literal></entry>
5589        </row>
5590
5591        <row>
5592         <entry> <literal>+</literal> </entry>
5593         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
5594         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
5595        </row>
5596
5597        <row>
5598         <entry> <literal>+</literal> </entry>
5599         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
5600         <entry><literal>time '04:00:00'</literal></entry>
5601        </row>
5602
5603        <row>
5604         <entry> <literal>-</literal> </entry>
5605         <entry><literal>- interval '23 hours'</literal></entry>
5606         <entry><literal>interval '-23:00:00'</literal></entry>
5607        </row>
5608
5609        <row>
5610         <entry> <literal>-</literal> </entry>
5611         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
5612         <entry><literal>integer '3'</literal></entry>
5613        </row>
5614
5615        <row>
5616         <entry> <literal>-</literal> </entry>
5617         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
5618         <entry><literal>date '2001-09-24'</literal></entry>
5619        </row>
5620
5621        <row>
5622         <entry> <literal>-</literal> </entry>
5623         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
5624         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
5625        </row>
5626
5627        <row>
5628         <entry> <literal>-</literal> </entry>
5629         <entry><literal>time '05:00' - time '03:00'</literal></entry>
5630         <entry><literal>interval '02:00:00'</literal></entry>
5631        </row>
5632
5633        <row>
5634         <entry> <literal>-</literal> </entry>
5635         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
5636         <entry><literal>time '03:00:00'</literal></entry>
5637        </row>
5638
5639        <row>
5640         <entry> <literal>-</literal> </entry>
5641         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
5642         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
5643        </row>
5644
5645        <row>
5646         <entry> <literal>-</literal> </entry>
5647         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
5648         <entry><literal>interval '1 day -01:00:00'</literal></entry>
5649        </row>
5650
5651        <row>
5652         <entry> <literal>-</literal> </entry>
5653         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
5654         <entry><literal>interval '1 day 15:00:00'</literal></entry>
5655        </row>
5656
5657        <row>
5658         <entry> <literal>*</literal> </entry>
5659         <entry><literal>900 * interval '1 second'</literal></entry>
5660         <entry><literal>interval '00:15:00'</literal></entry>
5661        </row>
5662
5663        <row>
5664         <entry> <literal>*</literal> </entry>
5665         <entry><literal>21 * interval '1 day'</literal></entry>
5666         <entry><literal>interval '21 days'</literal></entry>
5667        </row>
5668
5669        <row>
5670         <entry> <literal>*</literal> </entry>
5671         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
5672         <entry><literal>interval '03:30:00'</literal></entry>
5673        </row>
5674
5675        <row>
5676         <entry> <literal>/</literal> </entry>
5677         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
5678         <entry><literal>interval '00:40:00'</literal></entry>
5679        </row>
5680       </tbody>
5681      </tgroup>
5682     </table>
5683
5684    <indexterm>
5685     <primary>age</primary>
5686    </indexterm>
5687    <indexterm>
5688     <primary>clock_timestamp</primary>
5689    </indexterm>
5690    <indexterm>
5691     <primary>current_date</primary>
5692    </indexterm>
5693    <indexterm>
5694     <primary>current_time</primary>
5695    </indexterm>
5696    <indexterm>
5697     <primary>current_timestamp</primary>
5698    </indexterm>
5699    <indexterm>
5700     <primary>date_part</primary>
5701    </indexterm>
5702    <indexterm>
5703     <primary>date_trunc</primary>
5704    </indexterm>
5705    <indexterm>
5706     <primary>extract</primary>
5707    </indexterm>
5708    <indexterm>
5709     <primary>isfinite</primary>
5710    </indexterm>
5711    <indexterm>
5712     <primary>justify_days</primary>
5713    </indexterm>
5714    <indexterm>
5715     <primary>justify_hours</primary>
5716    </indexterm>
5717    <indexterm>
5718     <primary>justify_interval</primary>
5719    </indexterm>
5720    <indexterm>
5721     <primary>localtime</primary>
5722    </indexterm>
5723    <indexterm>
5724     <primary>localtimestamp</primary>
5725    </indexterm>
5726    <indexterm>
5727     <primary>now</primary>
5728    </indexterm>
5729    <indexterm>
5730     <primary>statement_timestamp</primary>
5731    </indexterm>
5732    <indexterm>
5733     <primary>timeofday</primary>
5734    </indexterm>
5735    <indexterm>
5736     <primary>transaction_timestamp</primary>
5737    </indexterm>
5738
5739     <table id="functions-datetime-table">
5740      <title>Date/Time Functions</title>
5741      <tgroup cols="5">
5742       <thead>
5743        <row>
5744         <entry>Function</entry>
5745         <entry>Return Type</entry>
5746         <entry>Description</entry>
5747         <entry>Example</entry>
5748         <entry>Result</entry>
5749        </row>
5750       </thead>
5751
5752       <tbody>
5753        <row>
5754         <entry><literal><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</literal></entry>
5755         <entry><type>interval</type></entry>
5756         <entry>Subtract arguments, producing a <quote>symbolic</> result that
5757         uses years and months</entry>
5758         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
5759         <entry><literal>43 years 9 mons 27 days</literal></entry>
5760        </row>
5761
5762        <row>
5763         <entry><literal><function>age</function>(<type>timestamp</type>)</literal></entry>
5764         <entry><type>interval</type></entry>
5765         <entry>Subtract from <function>current_date</function></entry>
5766         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
5767         <entry><literal>43 years 8 mons 3 days</literal></entry>
5768        </row>
5769
5770        <row>
5771         <entry><literal><function>clock_timestamp</function>()</literal></entry>
5772         <entry><type>timestamp with time zone</type></entry>
5773         <entry>Current date and time (changes during statement execution);
5774          see <xref linkend="functions-datetime-current">
5775         </entry>
5776         <entry></entry>
5777         <entry></entry>
5778        </row>
5779
5780        <row>
5781         <entry><literal><function>current_date</function></literal></entry>
5782         <entry><type>date</type></entry>
5783         <entry>Current date;
5784          see <xref linkend="functions-datetime-current">
5785         </entry>
5786         <entry></entry>
5787         <entry></entry>
5788        </row>
5789
5790        <row>
5791         <entry><literal><function>current_time</function></literal></entry>
5792         <entry><type>time with time zone</type></entry>
5793         <entry>Current time of day;
5794          see <xref linkend="functions-datetime-current">
5795         </entry>
5796         <entry></entry>
5797         <entry></entry>
5798        </row>
5799
5800        <row>
5801         <entry><literal><function>current_timestamp</function></literal></entry>
5802         <entry><type>timestamp with time zone</type></entry>
5803         <entry>Current date and time (start of current transaction);
5804          see <xref linkend="functions-datetime-current">
5805         </entry>
5806         <entry></entry>
5807         <entry></entry>
5808        </row>
5809
5810        <row>
5811         <entry><literal><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5812         <entry><type>double precision</type></entry>
5813         <entry>Get subfield (equivalent to <function>extract</function>);
5814          see <xref linkend="functions-datetime-extract">
5815         </entry>
5816         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5817         <entry><literal>20</literal></entry>
5818        </row>
5819
5820        <row>
5821         <entry><literal><function>date_part</function>(<type>text</type>, <type>interval</type>)</literal></entry>
5822         <entry><type>double precision</type></entry>
5823         <entry>Get subfield (equivalent to
5824          <function>extract</function>); see <xref linkend="functions-datetime-extract">
5825         </entry>
5826         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
5827         <entry><literal>3</literal></entry>
5828        </row>
5829
5830        <row>
5831         <entry><literal><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5832         <entry><type>timestamp</type></entry>
5833         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
5834         </entry>
5835         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5836         <entry><literal>2001-02-16 20:00:00</literal></entry>
5837        </row>
5838
5839        <row>
5840         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5841          <type>timestamp</type>)</literal></entry>
5842         <entry><type>double precision</type></entry>
5843         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5844         </entry>
5845         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
5846         <entry><literal>20</literal></entry>
5847        </row>
5848
5849        <row>
5850         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5851          <type>interval</type>)</literal></entry>
5852         <entry><type>double precision</type></entry>
5853         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5854         </entry>
5855         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
5856         <entry><literal>3</literal></entry>
5857        </row>
5858
5859        <row>
5860         <entry><literal><function>isfinite</function>(<type>timestamp</type>)</literal></entry>
5861         <entry><type>boolean</type></entry>
5862         <entry>Test for finite time stamp (not equal to infinity)</entry>
5863         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
5864         <entry><literal>true</literal></entry>
5865        </row>
5866
5867        <row>
5868         <entry><literal><function>isfinite</function>(<type>interval</type>)</literal></entry>
5869         <entry><type>boolean</type></entry>
5870         <entry>Test for finite interval</entry>
5871         <entry><literal>isfinite(interval '4 hours')</literal></entry>
5872         <entry><literal>true</literal></entry>
5873        </row>
5874
5875        <row>
5876         <entry><literal><function>justify_days</function>(<type>interval</type>)</literal></entry>
5877         <entry><type>interval</type></entry>
5878         <entry>Adjust interval so 30-day time periods are represented as months</entry>
5879         <entry><literal>justify_days(interval '30 days')</literal></entry>
5880         <entry><literal>1 month</literal></entry>
5881        </row>
5882
5883        <row>
5884         <entry><literal><function>justify_hours</function>(<type>interval</type>)</literal></entry>
5885         <entry><type>interval</type></entry>
5886         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
5887         <entry><literal>justify_hours(interval '24 hours')</literal></entry>
5888         <entry><literal>1 day</literal></entry>
5889        </row>
5890
5891        <row>
5892         <entry><literal><function>justify_interval</function>(<type>interval</type>)</literal></entry>
5893         <entry><type>interval</type></entry>
5894         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
5895         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
5896         <entry><literal>29 days 23:00:00</literal></entry>
5897        </row>
5898
5899        <row>
5900         <entry><literal><function>localtime</function></literal></entry>
5901         <entry><type>time</type></entry>
5902         <entry>Current time of day;
5903          see <xref linkend="functions-datetime-current">
5904         </entry>
5905         <entry></entry>
5906         <entry></entry>
5907        </row>
5908
5909        <row>
5910         <entry><literal><function>localtimestamp</function></literal></entry>
5911         <entry><type>timestamp</type></entry>
5912         <entry>Current date and time (start of current transaction);
5913          see <xref linkend="functions-datetime-current">
5914         </entry>
5915         <entry></entry>
5916         <entry></entry>
5917        </row>
5918
5919        <row>
5920         <entry><literal><function>now</function>()</literal></entry>
5921         <entry><type>timestamp with time zone</type></entry>
5922         <entry>Current date and time (start of current transaction);
5923          see <xref linkend="functions-datetime-current">
5924         </entry>
5925         <entry></entry>
5926         <entry></entry>
5927        </row>
5928
5929        <row>
5930         <entry><literal><function>statement_timestamp</function>()</literal></entry>
5931         <entry><type>timestamp with time zone</type></entry>
5932         <entry>Current date and time (start of current statement);
5933          see <xref linkend="functions-datetime-current">
5934         </entry>
5935         <entry></entry>
5936         <entry></entry>
5937        </row>
5938
5939        <row>
5940         <entry><literal><function>timeofday</function>()</literal></entry>
5941         <entry><type>text</type></entry>
5942         <entry>Current date and time
5943          (like <function>clock_timestamp</>, but as a <type>text</> string);
5944          see <xref linkend="functions-datetime-current">
5945         </entry>
5946         <entry></entry>
5947         <entry></entry>
5948        </row>
5949
5950        <row>
5951         <entry><literal><function>transaction_timestamp</function>()</literal></entry>
5952         <entry><type>timestamp with time zone</type></entry>
5953         <entry>Current date and time (start of current transaction);
5954          see <xref linkend="functions-datetime-current">
5955         </entry>
5956         <entry></entry>
5957         <entry></entry>
5958        </row>
5959       </tbody>
5960      </tgroup>
5961     </table>
5962
5963    <para>
5964     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
5965     supported:
5966 <synopsis>
5967 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
5968 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
5969 </synopsis>
5970     This expression yields true when two time periods (defined by their
5971     endpoints) overlap, false when they do not overlap.  The endpoints
5972     can be specified as pairs of dates, times, or time stamps; or as
5973     a date, time, or time stamp followed by an interval.
5974    </para>
5975
5976 <screen>
5977 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
5978        (DATE '2001-10-30', DATE '2002-10-30');
5979 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
5980 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
5981        (DATE '2001-10-30', DATE '2002-10-30');
5982 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
5983 </screen>
5984
5985   <para>
5986    When adding an <type>interval</type> value to (or subtracting an 
5987    <type>interval</type> value from) a <type>timestamp with time zone</type> 
5988    value, the days component advances (or decrements) the date of the 
5989    <type>timestamp with time zone</type> by the indicated number of days. 
5990    Across daylight saving time changes (with the session time zone set to a 
5991    time zone that recognizes DST), this means <literal>interval '1 day'</literal> 
5992    does not necessarily equal <literal>interval '24 hours'</literal>. 
5993    For example, with the session time zone set to <literal>CST7CDT</literal>,
5994    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
5995    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>, 
5996    while adding <literal>interval '24 hours'</literal> to the same initial 
5997    <type>timestamp with time zone</type> produces
5998    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
5999    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone 
6000    <literal>CST7CDT</literal>.
6001   </para>
6002
6003   <para>
6004    Note there can be ambiguity in the <literal>months</> returned by
6005    <function>age</> because different months have a different number of
6006    days.  <productname>PostgreSQL</>'s approach uses the month from the
6007    earlier of the two dates when calculating partial months.  For example,
6008    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6009    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6010    days</> because May has 31 days, while April has only 30.
6011   </para>
6012
6013   <sect2 id="functions-datetime-extract">
6014    <title><function>EXTRACT</function>, <function>date_part</function></title>
6015
6016    <indexterm>
6017     <primary>date_part</primary>
6018    </indexterm>
6019    <indexterm>
6020     <primary>extract</primary>
6021    </indexterm>
6022
6023 <synopsis>
6024 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6025 </synopsis>
6026
6027    <para>
6028     The <function>extract</function> function retrieves subfields
6029     such as year or hour from date/time values.
6030     <replaceable>source</replaceable> must be a value expression of
6031     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6032     (Expressions of type <type>date</type> will
6033     be cast to <type>timestamp</type> and can therefore be used as
6034     well.)  <replaceable>field</replaceable> is an identifier or
6035     string that selects what field to extract from the source value.
6036     The <function>extract</function> function returns values of type
6037     <type>double precision</type>.
6038     The following are valid field names:
6039
6040     <!-- alphabetical -->
6041     <variablelist>
6042      <varlistentry>
6043       <term><literal>century</literal></term>
6044       <listitem>
6045        <para>
6046         The century
6047        </para>
6048
6049 <screen>
6050 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6051 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6052 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6053 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6054 </screen>
6055
6056        <para>
6057         The first century starts at 0001-01-01 00:00:00 AD, although
6058         they did not know it at the time. This definition applies to all
6059         Gregorian calendar countries. There is no century number 0,
6060         you go from -1 to 1.
6061
6062         If you disagree with this, please write your complaint to:
6063         Pope, Cathedral Saint-Peter of Roma, Vatican.
6064        </para>
6065
6066        <para>
6067         <productname>PostgreSQL</productname> releases before 8.0 did not
6068         follow the conventional numbering of centuries, but just returned
6069         the year field divided by 100.
6070        </para>
6071       </listitem>
6072      </varlistentry>
6073
6074      <varlistentry>
6075       <term><literal>day</literal></term>
6076       <listitem>
6077        <para>
6078         The day (of the month) field (1 - 31)
6079        </para>
6080
6081 <screen>
6082 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6083 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6084 </screen>
6085       </listitem>
6086      </varlistentry>
6087
6088      <varlistentry>
6089       <term><literal>decade</literal></term>
6090       <listitem>
6091        <para>
6092         The year field divided by 10
6093        </para>
6094
6095 <screen>
6096 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6097 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6098 </screen>
6099       </listitem>
6100      </varlistentry>
6101
6102      <varlistentry>
6103       <term><literal>dow</literal></term>
6104       <listitem>
6105        <para>
6106         The day of the week as Sunday(<literal>0</>) to
6107         Saturday(<literal>6</>)
6108        </para>
6109
6110 <screen>
6111 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6112 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6113 </screen>
6114        <para>
6115         Note that <function>extract</function>'s day of the week numbering
6116         is different from that of the <function>to_char(...,
6117         'D')</function> function.
6118        </para>
6119
6120       </listitem>
6121      </varlistentry>
6122
6123      <varlistentry>
6124       <term><literal>doy</literal></term>
6125       <listitem>
6126        <para>
6127         The day of the year (1 - 365/366)
6128        </para>
6129
6130 <screen>
6131 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6132 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6133 </screen>
6134       </listitem>
6135      </varlistentry>
6136
6137      <varlistentry>
6138       <term><literal>epoch</literal></term>
6139       <listitem>
6140        <para>
6141         For <type>date</type> and <type>timestamp</type> values, the
6142         number of seconds since 1970-01-01 00:00:00-00 (can be negative);
6143         for <type>interval</type> values, the total number
6144         of seconds in the interval
6145        </para>
6146
6147 <screen>
6148 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-08');
6149 <lineannotation>Result: </lineannotation><computeroutput>982384720</computeroutput>
6150
6151 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6152 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6153 </screen>
6154
6155        <para>
6156         Here is how you can convert an epoch value back to a time
6157         stamp:
6158        </para>
6159
6160 <screen>
6161 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720 * INTERVAL '1 second';
6162 </screen>
6163       </listitem>
6164      </varlistentry>
6165
6166      <varlistentry>
6167       <term><literal>hour</literal></term>
6168       <listitem>
6169        <para>
6170         The hour field (0 - 23)
6171        </para>
6172
6173 <screen>
6174 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6175 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6176 </screen>
6177       </listitem>
6178      </varlistentry>
6179
6180      <varlistentry>
6181       <term><literal>isodow</literal></term>
6182       <listitem>
6183        <para>
6184         The day of the week as Monday(<literal>1</>) to
6185         Sunday(<literal>7</>)
6186        </para>
6187
6188 <screen>
6189 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6190 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6191 </screen>
6192        <para>
6193         This is identical to <literal>dow</> except for Sunday.  This
6194         matches the <acronym>ISO</> 8601 day of the week numbering.
6195        </para>
6196
6197       </listitem>
6198      </varlistentry>
6199
6200      <varlistentry>
6201       <term><literal>isoyear</literal></term>
6202       <listitem>
6203        <para>
6204         The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals).
6205        </para>
6206
6207 <screen>
6208 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6209 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6210 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6211 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6212 </screen>
6213
6214        <para>
6215         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.
6216        </para>
6217        <para>
6218         This field is not available in PostgreSQL releases prior to 8.3.
6219        </para>
6220       </listitem>
6221      </varlistentry>
6222
6223      <varlistentry>
6224       <term><literal>microseconds</literal></term>
6225       <listitem>
6226        <para>
6227         The seconds field, including fractional parts, multiplied by 1
6228         000 000.  Note that this includes full seconds.
6229        </para>
6230
6231 <screen>
6232 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6233 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6234 </screen>
6235       </listitem>
6236      </varlistentry>
6237
6238      <varlistentry>
6239       <term><literal>millennium</literal></term>
6240       <listitem>
6241        <para>
6242         The millennium
6243        </para>
6244
6245 <screen>
6246 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6247 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6248 </screen>
6249
6250        <para>
6251         Years in the 1900s are in the second millennium.
6252         The third millennium starts January 1, 2001.
6253        </para>
6254
6255        <para>
6256         <productname>PostgreSQL</productname> releases before 8.0 did not
6257         follow the conventional numbering of millennia, but just returned
6258         the year field divided by 1000.
6259        </para>
6260       </listitem>
6261      </varlistentry>
6262
6263      <varlistentry>
6264       <term><literal>milliseconds</literal></term>
6265       <listitem>
6266        <para>
6267         The seconds field, including fractional parts, multiplied by
6268         1000.  Note that this includes full seconds.
6269        </para>
6270
6271 <screen>
6272 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6273 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6274 </screen>
6275       </listitem>
6276      </varlistentry>
6277
6278      <varlistentry>
6279       <term><literal>minute</literal></term>
6280       <listitem>
6281        <para>
6282         The minutes field (0 - 59)
6283        </para>
6284
6285 <screen>
6286 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6287 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6288 </screen>
6289       </listitem>
6290      </varlistentry>
6291
6292      <varlistentry>
6293       <term><literal>month</literal></term>
6294       <listitem>
6295        <para>
6296         For <type>timestamp</type> values, the number of the month
6297         within the year (1 - 12) ; for <type>interval</type> values
6298         the number of months, modulo 12 (0 - 11)
6299        </para>
6300
6301 <screen>
6302 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6303 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6304
6305 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6306 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6307
6308 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6309 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6310 </screen>
6311       </listitem>
6312      </varlistentry>
6313
6314      <varlistentry>
6315       <term><literal>quarter</literal></term>
6316       <listitem>
6317        <para>
6318         The quarter of the year (1 - 4) that the day is in
6319        </para>
6320
6321 <screen>
6322 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6323 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6324 </screen>
6325       </listitem>
6326      </varlistentry>
6327
6328      <varlistentry>
6329       <term><literal>second</literal></term>
6330       <listitem>
6331        <para>
6332         The seconds field, including fractional parts (0 -
6333         59<footnote><simpara>60 if leap seconds are
6334         implemented by the operating system</simpara></footnote>)
6335        </para>
6336
6337 <screen>
6338 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6339 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6340
6341 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6342 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6343 </screen>
6344       </listitem>
6345      </varlistentry>
6346      <varlistentry>
6347       <term><literal>timezone</literal></term>
6348       <listitem>
6349        <para>
6350         The time zone offset from UTC, measured in seconds.  Positive values
6351         correspond to time zones east of UTC, negative values to
6352         zones west of UTC.
6353        </para>
6354       </listitem>
6355      </varlistentry>
6356
6357      <varlistentry>
6358       <term><literal>timezone_hour</literal></term>
6359       <listitem>
6360        <para>
6361         The hour component of the time zone offset
6362        </para>
6363       </listitem>
6364      </varlistentry>
6365
6366      <varlistentry>
6367       <term><literal>timezone_minute</literal></term>
6368       <listitem>
6369        <para>
6370         The minute component of the time zone offset
6371        </para>
6372       </listitem>
6373      </varlistentry>
6374
6375      <varlistentry>
6376       <term><literal>week</literal></term>
6377       <listitem>
6378        <para>
6379         The number of the week of the year that the day is in.  By definition
6380         (<acronym>ISO</acronym> 8601), the first week of a year
6381         contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
6382         week starts on Monday.)  In other words, the first Thursday of
6383         a year is in week 1 of that year.
6384        </para>
6385        <para>
6386         Because of this, it is possible for early January dates to be part of the 
6387         52nd or 53rd week of the previous year.  For example, <literal>2005-01-01</>
6388         is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of 
6389         the 52nd week of year 2005.
6390        </para>
6391
6392 <screen>
6393 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6394 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6395 </screen>
6396       </listitem>
6397      </varlistentry>
6398
6399      <varlistentry>
6400       <term><literal>year</literal></term>
6401       <listitem>
6402        <para>
6403         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting 
6404         <literal>BC</> years from <literal>AD</> years should be done with care.
6405        </para>
6406
6407 <screen>
6408 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6409 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6410 </screen>
6411       </listitem>
6412      </varlistentry>
6413
6414     </variablelist>
6415    </para>
6416
6417    <para>
6418     The <function>extract</function> function is primarily intended
6419     for computational processing.  For formatting date/time values for
6420     display, see <xref linkend="functions-formatting">.
6421    </para>
6422
6423    <para>
6424     The <function>date_part</function> function is modeled on the traditional
6425     <productname>Ingres</productname> equivalent to the
6426     <acronym>SQL</acronym>-standard function <function>extract</function>:
6427 <synopsis>
6428 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6429 </synopsis>
6430     Note that here the <replaceable>field</replaceable> parameter needs to
6431     be a string value, not a name.  The valid field names for
6432     <function>date_part</function> are the same as for
6433     <function>extract</function>.
6434    </para>
6435
6436 <screen>
6437 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
6438 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6439
6440 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
6441 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
6442 </screen>
6443
6444   </sect2>
6445
6446   <sect2 id="functions-datetime-trunc">
6447    <title><function>date_trunc</function></title>
6448
6449    <indexterm>
6450     <primary>date_trunc</primary>
6451    </indexterm>
6452
6453    <para>
6454     The function <function>date_trunc</function> is conceptually
6455     similar to the <function>trunc</function> function for numbers.
6456    </para>
6457
6458    <para>
6459 <synopsis>
6460 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6461 </synopsis>
6462     <replaceable>source</replaceable> is a value expression of type
6463     <type>timestamp</type> or <type>interval</>.
6464     (Values of type <type>date</type> and
6465     <type>time</type> are cast automatically, to <type>timestamp</type> or
6466     <type>interval</> respectively.)
6467     <replaceable>field</replaceable> selects to which precision to
6468     truncate the input value.  The return value is of type
6469     <type>timestamp</type> or <type>interval</>
6470     with all fields that are less significant than the
6471     selected one set to zero (or one, for day and month).
6472    </para>
6473
6474    <para>
6475     Valid values for <replaceable>field</replaceable> are:
6476     <simplelist>
6477      <member><literal>microseconds</literal></member>
6478      <member><literal>milliseconds</literal></member>
6479      <member><literal>second</literal></member>
6480      <member><literal>minute</literal></member>
6481      <member><literal>hour</literal></member>
6482      <member><literal>day</literal></member>
6483      <member><literal>week</literal></member>
6484      <member><literal>month</literal></member>
6485      <member><literal>quarter</literal></member>
6486      <member><literal>year</literal></member>
6487      <member><literal>decade</literal></member>
6488      <member><literal>century</literal></member>
6489      <member><literal>millennium</literal></member>
6490     </simplelist>
6491    </para>
6492
6493    <para>
6494     Examples:
6495 <screen>
6496 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
6497 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
6498
6499 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
6500 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
6501 </screen>
6502    </para>
6503   </sect2>
6504
6505   <sect2 id="functions-datetime-zoneconvert">
6506    <title><literal>AT TIME ZONE</literal></title>
6507
6508    <indexterm>
6509     <primary>time zone</primary>
6510     <secondary>conversion</secondary>
6511    </indexterm>
6512
6513    <indexterm>
6514     <primary>AT TIME ZONE</primary>
6515    </indexterm>
6516
6517    <para>
6518     The <literal>AT TIME ZONE</literal> construct allows conversions
6519     of time stamps to different time zones.  <xref
6520     linkend="functions-datetime-zoneconvert-table"> shows its
6521     variants.
6522    </para>
6523
6524     <table id="functions-datetime-zoneconvert-table">
6525      <title><literal>AT TIME ZONE</literal> Variants</title>
6526      <tgroup cols="3">
6527       <thead>
6528        <row>
6529         <entry>Expression</entry>
6530         <entry>Return Type</entry>
6531         <entry>Description</entry>
6532        </row>
6533       </thead>
6534
6535       <tbody>
6536        <row>
6537         <entry>
6538          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6539         </entry>
6540         <entry><type>timestamp with time zone</type></entry>
6541         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
6542        </row>
6543
6544        <row>
6545         <entry>
6546          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6547         </entry>
6548         <entry><type>timestamp without time zone</type></entry>
6549         <entry>Convert given time stamp <emphasis>with time zone</> to the new time zone</entry>
6550        </row>
6551
6552        <row>
6553         <entry>
6554          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6555         </entry>
6556         <entry><type>time with time zone</type></entry>
6557         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
6558        </row>
6559       </tbody>
6560      </tgroup>
6561     </table>
6562
6563    <para>
6564     In these expressions, the desired time zone <replaceable>zone</> can be
6565     specified either as a text string (e.g., <literal>'PST'</literal>)
6566     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
6567     In the text case, a time zone name can be specified in any of the ways
6568     described in <xref linkend="datatype-timezones">.
6569    </para>
6570
6571    <para>
6572     Examples (supposing that the local time zone is <literal>PST8PDT</>):
6573 <screen>
6574 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
6575 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
6576
6577 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
6578 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
6579 </screen>
6580     The first example takes a time stamp without time zone and interprets it as MST time
6581     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes 
6582     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
6583    </para>
6584
6585    <para>
6586     The function <literal><function>timezone</function>(<replaceable>zone</>,
6587     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
6588     <literal><replaceable>timestamp</> AT TIME ZONE
6589     <replaceable>zone</></literal>. 
6590    </para>
6591   </sect2>
6592
6593   <sect2 id="functions-datetime-current">
6594    <title>Current Date/Time</title>
6595
6596    <indexterm>
6597     <primary>date</primary>
6598     <secondary>current</secondary>
6599    </indexterm>
6600
6601    <indexterm>
6602     <primary>time</primary>
6603     <secondary>current</secondary>
6604    </indexterm>
6605
6606    <para>
6607     <productname>PostgreSQL</productname> provides a number of functions
6608     that return values related to the current date and time.  These
6609     SQL-standard functions all return values based on the start time of
6610     the current transaction:
6611 <synopsis>
6612 CURRENT_DATE
6613 CURRENT_TIME
6614 CURRENT_TIMESTAMP
6615 CURRENT_TIME(<replaceable>precision</replaceable>)
6616 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
6617 LOCALTIME
6618 LOCALTIMESTAMP
6619 LOCALTIME(<replaceable>precision</replaceable>)
6620 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
6621 </synopsis>
6622     </para>
6623
6624     <para>
6625      <function>CURRENT_TIME</function> and
6626      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
6627      <function>LOCALTIME</function> and
6628      <function>LOCALTIMESTAMP</function> deliver values without time zone.
6629     </para>
6630
6631     <para>
6632      <function>CURRENT_TIME</function>,
6633      <function>CURRENT_TIMESTAMP</function>,
6634      <function>LOCALTIME</function>, and
6635      <function>LOCALTIMESTAMP</function>
6636      can optionally be given
6637      a precision parameter, which causes the result to be rounded
6638      to that many fractional digits in the seconds field.  Without a precision parameter,
6639      the result is given to the full available precision.
6640     </para>
6641
6642    <para>
6643     Some examples:
6644 <screen>
6645 SELECT CURRENT_TIME;
6646 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
6647
6648 SELECT CURRENT_DATE;
6649 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
6650
6651 SELECT CURRENT_TIMESTAMP;
6652 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
6653
6654 SELECT CURRENT_TIMESTAMP(2);
6655 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
6656
6657 SELECT LOCALTIMESTAMP;
6658 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
6659 </screen>
6660    </para>
6661
6662    <para>
6663     Since these functions return
6664     the start time of the current transaction, their values do not
6665     change during the transaction. This is considered a feature:
6666     the intent is to allow a single transaction to have a consistent
6667     notion of the <quote>current</quote> time, so that multiple
6668     modifications within the same transaction bear the same
6669     time stamp.
6670    </para>
6671
6672    <note>
6673     <para>
6674      Other database systems might advance these values more
6675      frequently.
6676     </para>
6677    </note>
6678
6679    <para>
6680     <productname>PostgreSQL</productname> also provides functions that
6681     return the start time of the current statement, as well as the actual
6682     current time at the instant the function is called.  The complete list
6683     of non-SQL-standard time functions is:
6684 <synopsis>
6685 now()
6686 transaction_timestamp()
6687 statement_timestamp()
6688 clock_timestamp()
6689 timeofday()
6690 </synopsis>
6691    </para>
6692
6693    <para>
6694     <function>now()</> is a traditional <productname>PostgreSQL</productname>
6695     equivalent to <function>CURRENT_TIMESTAMP</function>.
6696     <function>transaction_timestamp()</> is likewise equivalent to
6697     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
6698     what it returns.
6699     <function>statement_timestamp()</> returns the start time of the current
6700     statement (more specifically, the time of receipt of the latest command
6701     message from the client).
6702     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
6703     return the same value during the first command of a transaction, but might
6704     differ during subsequent commands.
6705     <function>clock_timestamp()</> returns the actual current time, and
6706     therefore its value changes even within a single SQL command.
6707     <function>timeofday()</> is a historical
6708     <productname>PostgreSQL</productname> function.  Like
6709     <function>clock_timestamp()</>, it returns the actual current time,
6710     but as a formatted <type>text</> string rather than a <type>timestamp
6711     with time zone</> value.
6712    </para>
6713
6714    <para>
6715     All the date/time data types also accept the special literal value
6716     <literal>now</literal> to specify the current date and time (again,
6717     interpreted as the transaction start time).  Thus,
6718     the following three all return the same result:
6719 <programlisting>
6720 SELECT CURRENT_TIMESTAMP;
6721 SELECT now();
6722 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
6723 </programlisting>
6724    </para>
6725
6726     <tip>
6727      <para>
6728       You do not want to use the third form when specifying a <literal>DEFAULT</>
6729       clause while creating a table.  The system will convert <literal>now</literal>
6730       to a <type>timestamp</type> as soon as the constant is parsed, so that when
6731       the default value is needed,
6732       the time of the table creation would be used!  The first two
6733       forms will not be evaluated until the default value is used,
6734       because they are function calls.  Thus they will give the desired
6735       behavior of defaulting to the time of row insertion.
6736      </para>
6737     </tip>
6738   </sect2>
6739
6740   <sect2 id="functions-datetime-delay">
6741    <title>Delaying Execution</title>
6742
6743    <indexterm>
6744     <primary>pg_sleep</primary>
6745    </indexterm>
6746    <indexterm>
6747     <primary>sleep</primary>
6748    </indexterm>
6749    <indexterm>
6750     <primary>delay</primary>
6751    </indexterm>
6752
6753    <para>
6754     The following function is available to delay execution of the server
6755     process:
6756 <synopsis>
6757 pg_sleep(<replaceable>seconds</replaceable>)
6758 </synopsis>
6759
6760     <function>pg_sleep</function> makes the current session's process
6761     sleep until <replaceable>seconds</replaceable> seconds have
6762     elapsed.  <replaceable>seconds</replaceable> is a value of type
6763     <type>double precision</>, so fractional-second delays can be specified.
6764     For example:
6765
6766 <programlisting>
6767 SELECT pg_sleep(1.5);
6768 </programlisting>
6769    </para>
6770
6771    <note>
6772      <para>
6773       The effective resolution of the sleep interval is platform-specific;
6774       0.01 seconds is a common value.  The sleep delay will be at least as long
6775       as specified. It might be longer depending on factors such as server load.
6776      </para>
6777    </note>
6778
6779    <warning>
6780      <para>
6781       Make sure that your session does not hold more locks than necessary
6782       when calling <function>pg_sleep</function>.  Otherwise other sessions
6783       might have to wait for your sleeping process, slowing down the entire
6784       system.
6785      </para>
6786    </warning>
6787   </sect2>
6788
6789  </sect1>
6790
6791   
6792  <sect1 id="functions-enum">
6793   <title>Enum Support Functions</title>
6794
6795   <para>
6796    For enum types (described in <xref linkend="datatype-enum">),
6797    there are several functions that allow cleaner programming without
6798    hard-coding particular values of an enum type.
6799    These are listed in <xref linkend="functions-enum-table">. The examples
6800    assume an enum type created as:
6801
6802 <programlisting>
6803 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
6804 </programlisting>
6805
6806   </para>
6807
6808   <table id="functions-enum-table">
6809     <title>Enum Support Functions</title>
6810     <tgroup cols="4">
6811      <thead>
6812       <row>
6813        <entry>Function</entry>
6814        <entry>Description</entry>
6815        <entry>Example</entry>
6816        <entry>Example Result</entry>
6817       </row>
6818      </thead>
6819      <tbody>
6820       <row>
6821        <entry><literal>enum_first(anyenum)</literal></entry>
6822        <entry>Returns the first value of the input enum type</entry>
6823        <entry><literal>enum_first(null::rainbow)</literal></entry>
6824        <entry><literal>red</literal></entry>
6825       </row>
6826       <row>
6827        <entry><literal>enum_last(anyenum)</literal></entry>
6828        <entry>Returns the last value of the input enum type</entry>
6829        <entry><literal>enum_last(null::rainbow)</literal></entry>
6830        <entry><literal>purple</literal></entry>
6831       </row>
6832       <row>
6833        <entry><literal>enum_range(anyenum)</literal></entry>
6834        <entry>Returns all values of the input enum type in an ordered array</entry>
6835        <entry><literal>enum_range(null::rainbow)</literal></entry>
6836        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
6837       </row>
6838       <row>
6839        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
6840        <entry morerows="2">
6841         Returns the range between the two given enum values, as an ordered
6842         array. The values must be from the same enum type. If the first
6843         parameter is null, the result will start with the first value of
6844         the enum type.
6845         If the second parameter is null, the result will end with the last
6846         value of the enum type.
6847        </entry>
6848        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
6849        <entry><literal>{orange,yellow,green}</literal></entry>
6850       </row>
6851       <row>
6852        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
6853        <entry><literal>{red,orange,yellow,green}</literal></entry>
6854       </row>
6855       <row>
6856        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
6857        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
6858       </row>
6859      </tbody>
6860     </tgroup>
6861    </table>
6862
6863    <para>
6864     Notice that except for the two-argument form of <function>enum_range</>,
6865     these functions disregard the specific value passed to them; they care
6866     only about its declared data type.  Either null or a specific value of
6867     the type can be passed, with the same result.  It is more common to
6868     apply these functions to a table column or function argument than to
6869     a hardwired type name as suggested by the examples.
6870    </para>
6871  </sect1>
6872
6873  <sect1 id="functions-geometry">
6874   <title>Geometric Functions and Operators</title>
6875
6876    <para>
6877     The geometric types <type>point</type>, <type>box</type>,
6878     <type>lseg</type>, <type>line</type>, <type>path</type>,
6879     <type>polygon</type>, and <type>circle</type> have a large set of
6880     native support functions and operators, shown in <xref
6881     linkend="functions-geometry-op-table">, <xref
6882     linkend="functions-geometry-func-table">, and <xref
6883     linkend="functions-geometry-conv-table">.
6884    </para>
6885
6886    <caution>
6887     <para>
6888      Note that the <quote>same as</> operator, <literal>~=</>, represents
6889      the usual notion of equality for the <type>point</type>,
6890      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
6891      Some of these types also have an <literal>=</> operator, but
6892      <literal>=</> compares
6893      for equal <emphasis>areas</> only.  The other scalar comparison operators
6894      (<literal>&lt;=</> and so on) likewise compare areas for these types.
6895     </para>
6896    </caution>
6897
6898    <table id="functions-geometry-op-table">
6899      <title>Geometric Operators</title>
6900      <tgroup cols="3">
6901       <thead>
6902        <row>
6903         <entry>Operator</entry>
6904         <entry>Description</entry>
6905         <entry>Example</entry>
6906        </row>
6907       </thead>
6908       <tbody>
6909        <row>
6910         <entry> <literal>+</literal> </entry>
6911         <entry>Translation</entry>
6912         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
6913        </row>
6914        <row>
6915         <entry> <literal>-</literal> </entry>
6916         <entry>Translation</entry>
6917         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
6918        </row>
6919        <row>
6920         <entry> <literal>*</literal> </entry>
6921         <entry>Scaling/rotation</entry>
6922         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
6923        </row>
6924        <row>
6925         <entry> <literal>/</literal> </entry>
6926         <entry>Scaling/rotation</entry>
6927         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
6928        </row>
6929        <row>
6930         <entry> <literal>#</literal> </entry>
6931         <entry>Point or box of intersection</entry>
6932         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
6933        </row>
6934        <row>
6935         <entry> <literal>#</literal> </entry>
6936         <entry>Number of points in path or polygon</entry>
6937         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
6938        </row>
6939        <row>
6940         <entry> <literal>@-@</literal> </entry>
6941         <entry>Length or circumference</entry>
6942         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
6943        </row>
6944        <row>
6945         <entry> <literal>@@</literal> </entry>
6946         <entry>Center</entry>
6947         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
6948        </row>
6949        <row>
6950         <entry> <literal>##</literal> </entry>
6951         <entry>Closest point to first operand on second operand</entry>
6952         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
6953        </row>
6954        <row>
6955         <entry> <literal>&lt;-&gt;</literal> </entry>
6956         <entry>Distance between</entry>
6957         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
6958        </row>
6959        <row>
6960         <entry> <literal>&amp;&amp;</literal> </entry>
6961         <entry>Overlaps?</entry>
6962         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
6963        </row>
6964        <row>
6965         <entry> <literal>&lt;&lt;</literal> </entry>
6966         <entry>Is strictly left of?</entry>
6967         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
6968        </row>
6969        <row>
6970         <entry> <literal>&gt;&gt;</literal> </entry>
6971         <entry>Is strictly right of?</entry>
6972         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
6973        </row>
6974        <row>
6975         <entry> <literal>&amp;&lt;</literal> </entry>
6976         <entry>Does not extend to the right of?</entry>
6977         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
6978        </row>
6979        <row>
6980         <entry> <literal>&amp;&gt;</literal> </entry>
6981         <entry>Does not extend to the left of?</entry>
6982         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
6983        </row>
6984        <row>
6985         <entry> <literal>&lt;&lt;|</literal> </entry>
6986         <entry>Is strictly below?</entry>
6987         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
6988        </row>
6989        <row>
6990         <entry> <literal>|&gt;&gt;</literal> </entry>
6991         <entry>Is strictly above?</entry>
6992         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
6993        </row>
6994        <row>
6995         <entry> <literal>&amp;&lt;|</literal> </entry>
6996         <entry>Does not extend above?</entry>
6997         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
6998        </row>
6999        <row>
7000         <entry> <literal>|&amp;&gt;</literal> </entry>
7001         <entry>Does not extend below?</entry>
7002         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
7003        </row>
7004        <row>
7005         <entry> <literal>&lt;^</literal> </entry>
7006         <entry>Is below (allows touching)?</entry>
7007         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
7008        </row>
7009        <row>
7010         <entry> <literal>&gt;^</literal> </entry>
7011         <entry>Is above (allows touching)?</entry>
7012         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
7013        </row>
7014        <row>
7015         <entry> <literal>?#</literal> </entry>
7016         <entry>Intersects?</entry>
7017         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7018        </row>
7019        <row>
7020         <entry> <literal>?-</literal> </entry>
7021         <entry>Is horizontal?</entry>
7022         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7023        </row>
7024        <row>
7025         <entry> <literal>?-</literal> </entry>
7026         <entry>Are horizontally aligned?</entry>
7027         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7028        </row>
7029        <row>
7030         <entry> <literal>?|</literal> </entry>
7031         <entry>Is vertical?</entry>
7032         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7033        </row>
7034        <row>
7035         <entry> <literal>?|</literal> </entry>
7036         <entry>Are vertically aligned?</entry>
7037         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7038        </row>
7039        <row>
7040         <entry> <literal>?-|</literal> </entry>
7041         <entry>Is perpendicular?</entry>
7042         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7043        </row>
7044        <row>
7045         <entry> <literal>?||</literal> </entry>
7046         <entry>Are parallel?</entry>
7047         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7048        </row>
7049        <row>
7050         <entry> <literal>@&gt;</literal> </entry>
7051         <entry>Contains?</entry>
7052         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7053        </row>
7054        <row>
7055         <entry> <literal>&lt;@</literal> </entry>
7056         <entry>Contained in or on?</entry>
7057         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7058        </row>
7059        <row>
7060         <entry> <literal>~=</literal> </entry>
7061         <entry>Same as?</entry>
7062         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7063        </row>
7064       </tbody>
7065      </tgroup>
7066    </table>
7067
7068    <note>
7069     <para>
7070      Before <productname>PostgreSQL</productname> 8.2, the containment
7071      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7072      called <literal>~</> and <literal>@</>.  These names are still
7073      available, but are deprecated and will eventually be retired.
7074     </para>
7075    </note>
7076
7077    <indexterm>
7078     <primary>area</primary>
7079    </indexterm>
7080    <indexterm>
7081     <primary>center</primary>
7082    </indexterm>
7083    <indexterm>
7084     <primary>diameter</primary>
7085    </indexterm>
7086    <indexterm>
7087     <primary>height</primary>
7088    </indexterm>
7089    <indexterm>
7090     <primary>isclosed</primary>
7091    </indexterm>
7092    <indexterm>
7093     <primary>isopen</primary>
7094    </indexterm>
7095    <indexterm>
7096     <primary>length</primary>
7097    </indexterm>
7098    <indexterm>
7099     <primary>npoints</primary>
7100    </indexterm>
7101    <indexterm>
7102     <primary>pclose</primary>
7103    </indexterm>
7104    <indexterm>
7105     <primary>popen</primary>
7106    </indexterm>
7107    <indexterm>
7108     <primary>radius</primary>
7109    </indexterm>
7110    <indexterm>
7111     <primary>width</primary>
7112    </indexterm>
7113
7114    <table id="functions-geometry-func-table">
7115      <title>Geometric Functions</title>
7116      <tgroup cols="4">
7117       <thead>
7118        <row>
7119         <entry>Function</entry>
7120         <entry>Return Type</entry>
7121         <entry>Description</entry>
7122         <entry>Example</entry>
7123        </row>
7124       </thead>
7125       <tbody>
7126        <row>
7127         <entry><literal><function>area</function>(<replaceable>object</>)</literal></entry>
7128         <entry><type>double precision</type></entry>
7129         <entry>area</entry>
7130         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7131        </row>
7132        <row>
7133         <entry><literal><function>center</function>(<replaceable>object</>)</literal></entry>
7134         <entry><type>point</type></entry>
7135         <entry>center</entry>
7136         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7137        </row>
7138        <row>
7139         <entry><literal><function>diameter</function>(<type>circle</>)</literal></entry>
7140         <entry><type>double precision</type></entry>
7141         <entry>diameter of circle</entry>
7142         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7143        </row>
7144        <row>
7145         <entry><literal><function>height</function>(<type>box</>)</literal></entry>
7146         <entry><type>double precision</type></entry>
7147         <entry>vertical size of box</entry>
7148         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7149        </row>
7150        <row>
7151         <entry><literal><function>isclosed</function>(<type>path</>)</literal></entry>
7152         <entry><type>boolean</type></entry>
7153         <entry>a closed path?</entry>
7154         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7155        </row>
7156        <row>
7157         <entry><literal><function>isopen</function>(<type>path</>)</literal></entry>
7158         <entry><type>boolean</type></entry>
7159         <entry>an open path?</entry>
7160         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7161        </row>
7162        <row>
7163         <entry><literal><function>length</function>(<replaceable>object</>)</literal></entry>
7164         <entry><type>double precision</type></entry>
7165         <entry>length</entry>
7166         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7167        </row>
7168        <row>
7169         <entry><literal><function>npoints</function>(<type>path</>)</literal></entry>
7170         <entry><type>int</type></entry>
7171         <entry>number of points</entry>
7172         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7173        </row>
7174        <row>
7175         <entry><literal><function>npoints</function>(<type>polygon</>)</literal></entry>
7176         <entry><type>int</type></entry>
7177         <entry>number of points</entry>
7178         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7179        </row>
7180        <row>
7181         <entry><literal><function>pclose</function>(<type>path</>)</literal></entry>
7182         <entry><type>path</type></entry>
7183         <entry>convert path to closed</entry>
7184         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7185        </row>
7186 <![IGNORE[
7187 <!-- Not defined by this name. Implements the intersection operator '#' -->
7188        <row>
7189         <entry><literal><function>point</function>(<type>lseg</>, <type>lseg</>)</literal></entry>
7190         <entry><type>point</type></entry>
7191         <entry>intersection</entry>
7192         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7193        </row>
7194 ]]>
7195        <row>
7196         <entry><literal><function>popen</function>(<type>path</>)</literal></entry>
7197         <entry><type>path</type></entry>
7198         <entry>convert path to open</entry>
7199         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7200        </row>
7201        <row>
7202         <entry><literal><function>radius</function>(<type>circle</type>)</literal></entry>
7203         <entry><type>double precision</type></entry>
7204         <entry>radius of circle</entry>
7205         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7206        </row>
7207        <row>
7208         <entry><literal><function>width</function>(<type>box</>)</literal></entry>
7209         <entry><type>double precision</type></entry>
7210         <entry>horizontal size of box</entry>
7211         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7212        </row>
7213       </tbody>
7214      </tgroup>
7215    </table>
7216
7217    <table id="functions-geometry-conv-table">
7218      <title>Geometric Type Conversion Functions</title>
7219      <tgroup cols="4">
7220       <thead>
7221        <row>
7222         <entry>Function</entry>
7223         <entry>Return Type</entry>
7224         <entry>Description</entry>
7225         <entry>Example</entry>
7226        </row>
7227       </thead>
7228       <tbody>
7229        <row>
7230         <entry><literal><function>box</function>(<type>circle</type>)</literal></entry>
7231         <entry><type>box</type></entry>
7232         <entry>circle to box</entry>
7233         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7234        </row>
7235        <row>
7236         <entry><literal><function>box</function>(<type>point</type>, <type>point</type>)</literal></entry>
7237         <entry><type>box</type></entry>
7238         <entry>points to box</entry>
7239         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7240        </row>
7241        <row>
7242         <entry><literal><function>box</function>(<type>polygon</type>)</literal></entry>
7243         <entry><type>box</type></entry>
7244         <entry>polygon to box</entry>
7245         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7246        </row>
7247        <row>
7248         <entry><literal><function>circle</function>(<type>box</type>)</literal></entry>
7249         <entry><type>circle</type></entry>
7250         <entry>box to circle</entry>
7251         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7252        </row>
7253        <row>
7254         <entry><literal><function>circle</function>(<type>point</type>, <type>double precision</type>)</literal></entry>
7255         <entry><type>circle</type></entry>
7256         <entry>center and radius to circle</entry>
7257         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7258        </row>
7259        <row>
7260         <entry><literal><function>circle</function>(<type>polygon</type>)</literal></entry>
7261         <entry><type>circle</type></entry>
7262         <entry>polygon to circle</entry>
7263         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7264        </row>
7265        <row>
7266         <entry><literal><function>lseg</function>(<type>box</type>)</literal></entry>
7267         <entry><type>lseg</type></entry>
7268         <entry>box diagonal to line segment</entry>
7269         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7270        </row>
7271        <row>
7272         <entry><literal><function>lseg</function>(<type>point</type>, <type>point</type>)</literal></entry>
7273         <entry><type>lseg</type></entry>
7274         <entry>points to line segment</entry>
7275         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7276        </row>
7277        <row>
7278         <entry><literal><function>path</function>(<type>polygon</type>)</literal></entry>
7279         <entry><type>point</type></entry>
7280         <entry>polygon to path</entry>
7281         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7282        </row>
7283        <row>
7284         <entry><literal><function>point</function>(<type>double
7285          precision</type>, <type>double precision</type>)</literal></entry>
7286         <entry><type>point</type></entry>
7287         <entry>construct point</entry>
7288         <entry><literal>point(23.4, -44.5)</literal></entry>
7289        </row>
7290        <row>
7291         <entry><literal><function>point</function>(<type>box</type>)</literal></entry>
7292         <entry><type>point</type></entry>
7293         <entry>center of box</entry>
7294         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7295        </row>
7296        <row>
7297         <entry><literal><function>point</function>(<type>circle</type>)</literal></entry>
7298         <entry><type>point</type></entry>
7299         <entry>center of circle</entry>
7300         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7301        </row>
7302        <row>
7303         <entry><literal><function>point</function>(<type>lseg</type>)</literal></entry>
7304         <entry><type>point</type></entry>
7305         <entry>center of line segment</entry>
7306         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7307        </row>
7308        <row>
7309         <entry><literal><function>point</function>(<type>polygon</type>)</literal></entry>
7310         <entry><type>point</type></entry>
7311         <entry>center of polygon</entry>
7312         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7313        </row>
7314        <row>
7315         <entry><literal><function>polygon</function>(<type>box</type>)</literal></entry>
7316         <entry><type>polygon</type></entry>
7317         <entry>box to 4-point polygon</entry>
7318         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7319        </row>
7320        <row>
7321         <entry><literal><function>polygon</function>(<type>circle</type>)</literal></entry>
7322         <entry><type>polygon</type></entry>
7323         <entry>circle to 12-point polygon</entry>
7324         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7325        </row>
7326        <row>
7327         <entry><literal><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</literal></entry>
7328         <entry><type>polygon</type></entry>
7329         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
7330         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7331        </row>
7332        <row>
7333         <entry><literal><function>polygon</function>(<type>path</type>)</literal></entry>
7334         <entry><type>polygon</type></entry>
7335         <entry>path to polygon</entry>
7336         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7337        </row>
7338       </tbody>
7339      </tgroup>
7340    </table>
7341
7342     <para>
7343      It is possible to access the two component numbers of a <type>point</>
7344      as though it were an array with indices 0 and 1.  For example, if
7345      <literal>t.p</> is a <type>point</> column then
7346      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7347      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7348      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7349      as an array of two <type>point</> values.
7350     </para>
7351
7352     <para>
7353      The <function>area</function> function works for the types
7354      <type>box</type>, <type>circle</type>, and <type>path</type>.
7355      The <function>area</function> function only works on the
7356      <type>path</type> data type if the points in the
7357      <type>path</type> are non-intersecting.  For example, the
7358      <type>path</type>
7359      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7360      won't work, however, the following visually identical
7361      <type>path</type>
7362      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7363      will work.  If the concept of an intersecting versus
7364      non-intersecting <type>path</type> is confusing, draw both of the
7365      above <type>path</type>s side by side on a piece of graph paper.
7366     </para>
7367
7368   </sect1>
7369
7370
7371  <sect1 id="functions-net">
7372   <title>Network Address Functions and Operators</title>
7373
7374   <para>
7375    <xref linkend="cidr-inet-operators-table"> shows the operators
7376    available for the <type>cidr</type> and <type>inet</type> types.
7377    The operators <literal>&lt;&lt;</literal>,
7378    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
7379    <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
7380    consider only the network parts of the two addresses, ignoring any
7381    host part, and determine whether one network part is identical to
7382    or a subnet of the other.
7383   </para>
7384
7385     <table id="cidr-inet-operators-table">
7386      <title><type>cidr</type> and <type>inet</type> Operators</title>
7387      <tgroup cols="3">
7388       <thead>
7389        <row>
7390         <entry>Operator</entry>
7391         <entry>Description</entry>
7392         <entry>Example</entry>
7393        </row>
7394       </thead>
7395       <tbody>
7396        <row>
7397         <entry> <literal>&lt;</literal> </entry>
7398         <entry>is less than</entry>
7399         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
7400        </row>
7401        <row>
7402         <entry> <literal>&lt;=</literal> </entry>
7403         <entry>is less than or equal</entry>
7404         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
7405        </row>
7406        <row>
7407         <entry> <literal>=</literal> </entry>
7408         <entry>equals</entry>
7409         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
7410        </row>
7411        <row>
7412         <entry> <literal>&gt;=</literal> </entry>
7413         <entry>is greater or equal</entry>
7414         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
7415        </row>
7416        <row>
7417         <entry> <literal>&gt;</literal> </entry>
7418         <entry>is greater than</entry>
7419         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
7420        </row>
7421        <row>
7422         <entry> <literal>&lt;&gt;</literal> </entry>
7423         <entry>is not equal</entry>
7424         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
7425        </row>
7426        <row>
7427         <entry> <literal>&lt;&lt;</literal> </entry>
7428         <entry>is contained within</entry>
7429         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
7430        </row>
7431        <row>
7432         <entry> <literal>&lt;&lt;=</literal> </entry>
7433         <entry>is contained within or equals</entry>
7434         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
7435        </row>
7436        <row>
7437         <entry> <literal>&gt;&gt;</literal> </entry>
7438         <entry>contains</entry>
7439         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
7440        </row>
7441        <row>
7442         <entry> <literal>&gt;&gt;=</literal> </entry>
7443         <entry>contains or equals</entry>
7444         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
7445        </row>
7446        <row>
7447         <entry> <literal>~</literal> </entry>
7448         <entry>bitwise NOT</entry>
7449         <entry><literal>~ inet '192.168.1.6'</literal></entry>
7450        </row>
7451        <row>
7452         <entry> <literal>&amp;</literal> </entry>
7453         <entry>bitwise AND</entry>
7454         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
7455        </row>
7456        <row>
7457         <entry> <literal>|</literal> </entry>
7458         <entry>bitwise OR</entry>
7459         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
7460        </row>
7461        <row>
7462         <entry> <literal>+</literal> </entry>
7463         <entry>addition</entry>
7464         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
7465        </row>
7466        <row>
7467         <entry> <literal>-</literal> </entry>
7468         <entry>subtraction</entry>
7469         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
7470        </row>
7471        <row>
7472         <entry> <literal>-</literal> </entry>
7473         <entry>subtraction</entry>
7474         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
7475        </row>
7476       </tbody>
7477      </tgroup>
7478     </table>
7479
7480   <para>
7481    <xref linkend="cidr-inet-functions-table"> shows the functions
7482    available for use with the <type>cidr</type> and <type>inet</type>
7483    types.  The <function>host</function>,
7484    <function>text</function>, and <function>abbrev</function>
7485    functions are primarily intended to offer alternative display
7486    formats.
7487   </para>
7488
7489     <table id="cidr-inet-functions-table">
7490      <title><type>cidr</type> and <type>inet</type> Functions</title>
7491      <tgroup cols="5">
7492       <thead>
7493        <row>
7494         <entry>Function</entry>
7495         <entry>Return Type</entry>
7496         <entry>Description</entry>
7497         <entry>Example</entry>
7498         <entry>Result</entry>
7499        </row>
7500       </thead>
7501       <tbody>
7502        <row>
7503         <entry><literal><function>abbrev</function>(<type>inet</type>)</literal></entry>
7504         <entry><type>text</type></entry>
7505         <entry>abbreviated display format as text</entry>
7506         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
7507         <entry><literal>10.1.0.0/16</literal></entry>
7508        </row>
7509        <row>
7510         <entry><literal><function>abbrev</function>(<type>cidr</type>)</literal></entry>
7511         <entry><type>text</type></entry>
7512         <entry>abbreviated display format as text</entry>
7513         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
7514         <entry><literal>10.1/16</literal></entry>
7515        </row>
7516        <row>
7517         <entry><literal><function>broadcast</function>(<type>inet</type>)</literal></entry>
7518         <entry><type>inet</type></entry>
7519         <entry>broadcast address for network</entry>
7520         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
7521         <entry><literal>192.168.1.255/24</literal></entry>
7522        </row>
7523        <row>
7524         <entry><literal><function>family</function>(<type>inet</type>)</literal></entry>
7525         <entry><type>int</type></entry>
7526         <entry>extract family of address; <literal>4</literal> for IPv4,
7527          <literal>6</literal> for IPv6</entry>
7528         <entry><literal>family('::1')</literal></entry>
7529         <entry><literal>6</literal></entry>
7530        </row>
7531        <row>
7532         <entry><literal><function>host</function>(<type>inet</type>)</literal></entry>
7533         <entry><type>text</type></entry>
7534         <entry>extract IP address as text</entry>
7535         <entry><literal>host('192.168.1.5/24')</literal></entry>
7536         <entry><literal>192.168.1.5</literal></entry>
7537        </row>
7538        <row>
7539         <entry><literal><function>hostmask</function>(<type>inet</type>)</literal></entry>
7540         <entry><type>inet</type></entry>
7541         <entry>construct host mask for network</entry>
7542         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
7543         <entry><literal>0.0.0.3</literal></entry>
7544        </row>
7545        <row>
7546         <entry><literal><function>masklen</function>(<type>inet</type>)</literal></entry>
7547         <entry><type>int</type></entry>
7548         <entry>extract netmask length</entry>
7549         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
7550         <entry><literal>24</literal></entry>
7551        </row>
7552        <row>
7553         <entry><literal><function>netmask</function>(<type>inet</type>)</literal></entry>
7554         <entry><type>inet</type></entry>
7555         <entry>construct netmask for network</entry>
7556         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
7557         <entry><literal>255.255.255.0</literal></entry>
7558        </row>
7559        <row>
7560         <entry><literal><function>network</function>(<type>inet</type>)</literal></entry>
7561         <entry><type>cidr</type></entry>
7562         <entry>extract network part of address</entry>
7563         <entry><literal>network('192.168.1.5/24')</literal></entry>
7564         <entry><literal>192.168.1.0/24</literal></entry>
7565        </row>
7566        <row>
7567         <entry><literal><function>set_masklen</function>(<type>inet</type>, <type>int</type>)</literal></entry>
7568         <entry><type>inet</type></entry>
7569         <entry>set netmask length for <type>inet</type> value</entry>
7570         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
7571         <entry><literal>192.168.1.5/16</literal></entry>
7572        </row>
7573        <row>
7574         <entry><literal><function>set_masklen</function>(<type>cidr</type>, <type>int</type>)</literal></entry>
7575         <entry><type>cidr</type></entry>
7576         <entry>set netmask length for <type>cidr</type> value</entry>
7577         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
7578         <entry><literal>192.168.0.0/16</literal></entry>
7579        </row>
7580        <row>
7581         <entry><literal><function>text</function>(<type>inet</type>)</literal></entry>
7582         <entry><type>text</type></entry>
7583         <entry>extract IP address and netmask length as text</entry>
7584         <entry><literal>text(inet '192.168.1.5')</literal></entry>
7585         <entry><literal>192.168.1.5/32</literal></entry>
7586        </row>
7587       </tbody>
7588      </tgroup>
7589     </table>
7590
7591   <para>
7592    Any <type>cidr</> value can be cast to <type>inet</> implicitly
7593    or explicitly; therefore, the functions shown above as operating on
7594    <type>inet</> also work on <type>cidr</> values.  (Where there are
7595    separate functions for <type>inet</> and <type>cidr</>, it is because
7596    the behavior should be different for the two cases.)
7597    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
7598    When this is done, any bits to the right of the netmask are silently zeroed
7599    to create a valid <type>cidr</> value.
7600    In addition,
7601    you can cast a text value to <type>inet</> or <type>cidr</>
7602    using normal casting syntax: for example,
7603    <literal>inet(<replaceable>expression</>)</literal> or
7604    <literal><replaceable>colname</>::cidr</literal>.
7605   </para>
7606
7607   <para>
7608    <xref linkend="macaddr-functions-table"> shows the functions
7609    available for use with the <type>macaddr</type> type.  The function
7610    <literal><function>trunc</function>(<type>macaddr</type>)</literal> returns a MAC
7611    address with the last 3 bytes set to zero.  This can be used to
7612    associate the remaining prefix with a manufacturer.
7613   </para>
7614
7615     <table id="macaddr-functions-table">
7616      <title><type>macaddr</type> Functions</title>
7617      <tgroup cols="5">
7618       <thead>
7619        <row>
7620         <entry>Function</entry>
7621         <entry>Return Type</entry>
7622         <entry>Description</entry>
7623         <entry>Example</entry>
7624         <entry>Result</entry>
7625        </row>
7626       </thead>
7627       <tbody>
7628        <row>
7629         <entry><literal><function>trunc</function>(<type>macaddr</type>)</literal></entry>
7630         <entry><type>macaddr</type></entry>
7631         <entry>set last 3 bytes to zero</entry>
7632         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
7633         <entry><literal>12:34:56:00:00:00</literal></entry>
7634        </row>
7635       </tbody>
7636      </tgroup>
7637     </table>
7638
7639    <para>
7640     The <type>macaddr</type> type also supports the standard relational
7641     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
7642     lexicographical ordering.
7643    </para>
7644
7645   </sect1>
7646
7647
7648  <sect1 id="functions-textsearch">
7649   <title>Text Search Functions and Operators</title>
7650
7651    <indexterm zone="datatype-textsearch">
7652     <primary>full text search</primary>
7653     <secondary>functions and operators</secondary>
7654    </indexterm>
7655
7656    <indexterm zone="datatype-textsearch">
7657     <primary>text search</primary>
7658     <secondary>functions and operators</secondary>
7659    </indexterm>
7660
7661   <para>
7662    <xref linkend="textsearch-operators-table">,
7663    <xref linkend="textsearch-functions-table"> and
7664    <xref linkend="textsearch-functions-debug-table">
7665    summarize the functions and operators that are provided
7666    for full text searching.  See <xref linkend="textsearch"> for a detailed
7667    explanation of <productname>PostgreSQL</productname>'s text search
7668    facility.
7669   </para>
7670
7671     <table id="textsearch-operators-table">
7672      <title>Text Search Operators</title>
7673      <tgroup cols="4">
7674       <thead>
7675        <row>
7676         <entry>Operator</entry>
7677         <entry>Description</entry>
7678         <entry>Example</entry>
7679         <entry>Result</entry>
7680        </row>
7681       </thead>
7682       <tbody>
7683        <row>
7684         <entry> <literal>@@</literal> </entry>
7685         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
7686         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
7687         <entry><literal>t</literal></entry>
7688        </row>
7689        <row>
7690         <entry> <literal>@@@</literal> </entry>
7691         <entry>same as <literal>@@</>, but see <xref linkend="textsearch-indexes"></entry>
7692         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
7693         <entry><literal>t</literal></entry>
7694        </row>
7695        <row>
7696         <entry> <literal>||</literal> </entry>
7697         <entry>concatenate <type>tsvector</>s</entry>
7698         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
7699         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
7700        </row>
7701        <row>
7702         <entry> <literal>&amp;&amp;</literal> </entry>
7703         <entry>AND <type>tsquery</>s together</entry>
7704         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
7705         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
7706        </row>
7707        <row>
7708         <entry> <literal>||</literal> </entry>
7709         <entry>OR <type>tsquery</>s together</entry>
7710         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
7711         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
7712        </row>
7713        <row>
7714         <entry> <literal>!!</literal> </entry>
7715         <entry>negate a <type>tsquery</></entry>
7716         <entry><literal>!! 'cat'::tsquery</literal></entry>
7717         <entry><literal>!'cat'</literal></entry>
7718        </row>
7719        <row>
7720         <entry> <literal>@&gt;</literal> </entry>
7721         <entry><type>tsquery</> contains another ?</entry>
7722         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
7723         <entry><literal>f</literal></entry>
7724        </row>
7725        <row>
7726         <entry> <literal>&lt;@</literal> </entry>
7727         <entry><type>tsquery</> is contained in ?</entry>
7728         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
7729         <entry><literal>t</literal></entry>
7730        </row>
7731       </tbody>
7732      </tgroup>
7733     </table>
7734
7735     <note>
7736      <para>
7737       The <type>tsquery</> containment operators consider only the lexemes
7738       listed in the two queries, ignoring the combining operators.
7739      </para>
7740     </note>
7741
7742     <para>
7743      In addition to the operators shown in the table, the ordinary B-tree
7744      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
7745      for types <type>tsvector</> and <type>tsquery</>.  These are not very
7746      useful for text searching but allow, for example, unique indexes to be
7747      built on columns of these types.
7748     </para>
7749
7750     <table id="textsearch-functions-table">
7751      <title>Text Search Functions</title>
7752      <tgroup cols="5">
7753       <thead>
7754        <row>
7755         <entry>Function</entry>
7756         <entry>Return Type</entry>
7757         <entry>Description</entry>
7758         <entry>Example</entry>
7759         <entry>Result</entry>
7760        </row>
7761       </thead>
7762       <tbody>
7763        <row>
7764         <entry><literal><function>to_tsvector</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</literal></entry>
7765         <entry><type>tsvector</type></entry>
7766         <entry>reduce document text to <type>tsvector</></entry>
7767         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
7768         <entry><literal>'fat':2 'rat':3</literal></entry>
7769        </row>
7770        <row>
7771         <entry><literal><function>length</function>(<type>tsvector</>)</literal></entry>
7772         <entry><type>integer</type></entry>
7773         <entry>number of lexemes in <type>tsvector</></entry>
7774         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7775         <entry><literal>3</literal></entry>
7776        </row>
7777        <row>
7778         <entry><literal><function>setweight</function>(<type>tsvector</>, <type>"char"</>)</literal></entry>
7779         <entry><type>tsvector</type></entry>
7780         <entry>assign weight to each element of <type>tsvector</></entry>
7781         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
7782         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
7783        </row>
7784        <row>
7785         <entry><literal><function>strip</function>(<type>tsvector</>)</literal></entry>
7786         <entry><type>tsvector</type></entry>
7787         <entry>remove positions and weights from <type>tsvector</></entry>
7788         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7789         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
7790        </row>
7791        <row>
7792         <entry><literal><function>to_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7793         <entry><type>tsquery</type></entry>
7794         <entry>normalize words and convert to <type>tsquery</></entry>
7795         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
7796         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7797        </row>
7798        <row>
7799         <entry><literal><function>plainto_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7800         <entry><type>tsquery</type></entry>
7801         <entry>produce <type>tsquery</> ignoring punctuation</entry>
7802         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
7803         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7804        </row>
7805        <row>
7806         <entry><literal><function>numnode</function>(<type>tsquery</>)</literal></entry>
7807         <entry><type>integer</type></entry>
7808         <entry>number of lexemes plus operators in <type>tsquery</></entry>
7809         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
7810         <entry><literal>5</literal></entry>
7811        </row>
7812        <row>
7813         <entry><literal><function>querytree</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</literal></entry>
7814         <entry><type>text</type></entry>
7815         <entry>get indexable part of a <type>tsquery</></entry>
7816         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
7817         <entry><literal>'foo'</literal></entry>
7818        </row>
7819        <row>
7820         <entry><literal><function>ts_rank</function>(<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>)</literal></entry>
7821         <entry><type>float4</type></entry>
7822         <entry>rank document for query</entry>
7823         <entry><literal>ts_rank(textsearch, query)</literal></entry>
7824         <entry><literal>0.818</literal></entry>
7825        </row>
7826        <row>
7827         <entry><literal><function>ts_rank_cd</function>(<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>)</literal></entry>
7828         <entry><type>float4</type></entry>
7829         <entry>rank document for query using cover density</entry>
7830         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
7831         <entry><literal>2.01317</literal></entry>
7832        </row>
7833        <row>
7834         <entry><literal><function>ts_headline</function>(<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>)</literal></entry>
7835         <entry><type>text</type></entry>
7836         <entry>display a query match</entry>
7837         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
7838         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
7839        </row>
7840        <row>
7841         <entry><literal><function>ts_rewrite</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">target</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">substitute</replaceable> <type>tsquery</>)</literal></entry>
7842         <entry><type>tsquery</type></entry>
7843         <entry>replace target with substitute within query</entry>
7844         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
7845         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7846        </row>
7847        <row>
7848         <entry><literal><function>ts_rewrite</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</literal></entry>
7849         <entry><type>tsquery</type></entry>
7850         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
7851         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
7852         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7853        </row>
7854        <row>
7855         <entry><literal><function>get_current_ts_config</function>()</literal></entry>
7856         <entry><type>regconfig</type></entry>
7857         <entry>get default text search configuration</entry>
7858         <entry><literal>get_current_ts_config()</literal></entry>
7859         <entry><literal>english</literal></entry>
7860        </row>
7861        <row>
7862         <entry><literal><function>tsvector_update_trigger</function>()</literal></entry>
7863         <entry><type>trigger</type></entry>
7864         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7865         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
7866         <entry><literal></literal></entry>
7867        </row>
7868        <row>
7869         <entry><literal><function>tsvector_update_trigger_column</function>()</literal></entry>
7870         <entry><type>trigger</type></entry>
7871         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7872         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
7873         <entry><literal></literal></entry>
7874         <entry><literal></literal></entry>
7875        </row>
7876       </tbody>
7877      </tgroup>
7878     </table>
7879
7880   <note>
7881    <para>
7882     All the text search functions that accept an optional <type>regconfig</>
7883     argument will use the configuration specified by
7884     <xref linkend="guc-default-text-search-config">
7885     when that argument is omitted.
7886    </para>
7887   </note>
7888
7889   <para>
7890    The functions in
7891    <xref linkend="textsearch-functions-debug-table">
7892    are listed separately because they are not usually used in everyday text
7893    searching operations.  They are helpful for development and debugging
7894    of new text search configurations.
7895   </para>
7896
7897     <table id="textsearch-functions-debug-table">
7898      <title>Text Search Debugging Functions</title>
7899      <tgroup cols="5">
7900       <thead>
7901        <row>
7902         <entry>Function</entry>
7903         <entry>Return Type</entry>
7904         <entry>Description</entry>
7905         <entry>Example</entry>
7906         <entry>Result</entry>
7907        </row>
7908       </thead>
7909       <tbody>
7910        <row>
7911         <entry><literal><function>ts_debug</function>(<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[]</>)</literal></entry>
7912         <entry><type>setof record</type></entry>
7913         <entry>test a configuration</entry>
7914         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
7915         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
7916        </row>
7917        <row>
7918         <entry><literal><function>ts_lexize</function>(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</literal></entry>
7919         <entry><type>text[]</type></entry>
7920         <entry>test a dictionary</entry>
7921         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
7922         <entry><literal>{star}</literal></entry>
7923        </row>
7924        <row>
7925         <entry><literal><function>ts_parse</function>(<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</>)</literal></entry>
7926         <entry><type>setof record</type></entry>
7927         <entry>test a parser</entry>
7928         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
7929         <entry><literal>(1,foo) ...</literal></entry>
7930        </row>
7931        <row>
7932         <entry><literal><function>ts_parse</function>(<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</>)</literal></entry>
7933         <entry><type>setof record</type></entry>
7934         <entry>test a parser</entry>
7935         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
7936         <entry><literal>(1,foo) ...</literal></entry>
7937        </row>
7938        <row>
7939         <entry><literal><function>ts_token_type</function>(<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</>)</literal></entry>
7940         <entry><type>setof record</type></entry>
7941         <entry>get token types defined by parser</entry>
7942         <entry><literal>ts_token_type('default')</literal></entry>
7943         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
7944        </row>
7945        <row>
7946         <entry><literal><function>ts_token_type</function>(<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</>)</literal></entry>
7947         <entry><type>setof record</type></entry>
7948         <entry>get token types defined by parser</entry>
7949         <entry><literal>ts_token_type(3722)</literal></entry>
7950         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
7951        </row>
7952        <row>
7953         <entry><literal><function>ts_stat</function>(<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</>)</literal></entry>
7954         <entry><type>setof record</type></entry>
7955         <entry>get statistics of a <type>tsvector</> column</entry>
7956         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
7957         <entry><literal>(foo,10,15) ...</literal></entry>
7958        </row>
7959       </tbody>
7960      </tgroup>
7961     </table>
7962
7963  </sect1>
7964
7965
7966  <sect1 id="functions-xml">
7967   <title>XML Functions</title>
7968
7969   <para>
7970    The functions and function-like expressions described in this
7971    section operate on values of type <type>xml</type>.  Check <xref
7972    linkend="datatype-xml"> for information about the <type>xml</type>
7973    type.  The function-like expressions <function>xmlparse</function>
7974    and <function>xmlserialize</function> for converting to and from
7975    type <type>xml</type> are not repeated here.  Use of many of these
7976    functions requires the installation to have been built
7977    with <command>configure --with-libxml</>.
7978   </para>
7979
7980   <sect2>
7981    <title>Producing XML Content</title>
7982
7983    <para>
7984     A set of functions and function-like expressions are available for
7985     producing XML content from SQL data.  As such, they are
7986     particularly suitable for formatting query results into XML
7987     documents for processing in client applications.
7988    </para>
7989
7990    <sect3>
7991     <title><literal>xmlcomment</literal></title>
7992
7993     <indexterm>
7994      <primary>xmlcomment</primary>
7995     </indexterm>
7996
7997 <synopsis>
7998 <function>xmlcomment</function>(<replaceable>text</replaceable>)
7999 </synopsis>
8000
8001     <para>
8002      The function <function>xmlcomment</function> creates an XML value
8003      containing an XML comment with the specified text as content.
8004      The text cannot contain <literal>--</literal> or end with a
8005      <literal>-</literal> so that the resulting construct is a valid
8006      XML comment.  If the argument is null, the result is null.
8007     </para>
8008
8009     <para>
8010      Example:
8011 <screen><![CDATA[
8012 SELECT xmlcomment('hello');
8013
8014   xmlcomment
8015 --------------
8016  <!--hello-->
8017 ]]></screen>
8018     </para>
8019    </sect3>
8020
8021    <sect3>
8022     <title><literal>xmlconcat</literal></title>
8023
8024     <indexterm>
8025      <primary>xmlconcat</primary>
8026     </indexterm>
8027
8028  <synopsis>
8029  <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8030  </synopsis>
8031  
8032     <para>
8033      The function <function>xmlconcat</function> concatenates a list
8034      of individual XML values to create a single value containing an
8035      XML content fragment.  Null values are omitted; the result is
8036      only null if there are no nonnull arguments.
8037     </para>
8038
8039     <para>
8040      Example:
8041 <screen><![CDATA[
8042 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8043
8044       xmlconcat
8045 ----------------------
8046  <abc/><bar>foo</bar>
8047 ]]></screen>
8048     </para>
8049
8050     <para>
8051      XML declarations, if present, are combined as follows.  If all
8052      argument values have the same XML version declaration, that
8053      version is used in the result, else no version is used.  If all
8054      argument values have the standalone declaration value
8055      <quote>yes</quote>, then that value is used in the result.  If
8056      all argument values have a standalone declaration value and at
8057      least one is <quote>no</quote>, then that is used in the result.
8058      Else the result will have no standalone declaration.  If the
8059      result is determined to require a standalone declaration but no
8060      version declaration, a version declaration with version 1.0 will
8061      be used because XML requires an XML declaration to contain a
8062      version declaration.  Encoding declarations are ignored and
8063      removed in all cases.
8064     </para>
8065
8066     <para>
8067      Example:
8068 <screen><![CDATA[
8069 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
8070
8071              xmlconcat
8072 -----------------------------------
8073  <?xml version="1.1"?><foo/><bar/>
8074 ]]></screen>
8075     </para>
8076    </sect3>
8077  
8078    <sect3>
8079     <title><literal>xmlelement</literal></title>
8080  
8081    <indexterm>
8082     <primary>xmlelement</primary>
8083    </indexterm>
8084  
8085 <synopsis>
8086  <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>)
8087  </synopsis>
8088  
8089     <para>
8090      The <function>xmlelement</function> expression produces an XML
8091      element with the given name, attributes, and content.
8092     </para>
8093
8094     <para>
8095      Examples:
8096 <screen><![CDATA[
8097 SELECT xmlelement(name foo);
8098
8099  xmlelement
8100 ------------
8101  <foo/>
8102
8103 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8104
8105     xmlelement
8106 ------------------
8107  <foo bar="xyz"/>
8108
8109 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8110
8111              xmlelement
8112 -------------------------------------
8113  <foo bar="2007-01-26">content</foo>
8114 ]]></screen>
8115     </para>
8116
8117     <para>
8118      Element and attribute names that are not valid XML names are
8119      escaped by replacing the offending characters by the sequence
8120      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8121      <replaceable>HHHH</replaceable> is the character's Unicode
8122      codepoint in hexadecimal notation.  For example:
8123 <screen><![CDATA[
8124 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
8125
8126             xmlelement
8127 ----------------------------------
8128  <foo_x0024_bar a_x0026_b="xyz"/>
8129 ]]></screen>
8130     </para>
8131
8132     <para>
8133      An explicit attribute name need not be specified if the attribute
8134      value is a column reference, in which case the column's name will
8135      be used as attribute name by default.  In any other case, the
8136      attribute must be given an explicit name.  So this example is
8137      valid:
8138 <screen>
8139 CREATE TABLE test (a xml, b xml);
8140 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8141 </screen>
8142      But these are not:
8143 <screen>
8144 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8145 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8146 </screen>
8147     </para>
8148
8149     <para>
8150      Element content, if specified, will be formatted according to
8151      data type.  If the content is itself of type <type>xml</type>,
8152      complex XML documents can be constructed.  For example:
8153 <screen><![CDATA[
8154 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8155                             xmlelement(name abc),
8156                             xmlcomment('test'),
8157                             xmlelement(name xyz));
8158
8159                   xmlelement
8160 ----------------------------------------------
8161  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
8162 ]]></screen>
8163
8164      Content of other types will be formatted into valid XML character
8165      data.  This means in particular that the characters &lt;, &gt;,
8166      and &amp; will be converted to entities.  Binary data (data type
8167      <type>bytea</type>) will be represented in base64 or hex
8168      encoding, depending on the setting of the configuration parameter
8169      <xref linkend="guc-xmlbinary">.  The particular behavior for
8170      individual data types is expected to evolve in order to align the
8171      SQL and PostgreSQL data types with the XML Schema specification,
8172      at which point a more precise description will appear.
8173     </para>
8174    </sect3>
8175  
8176    <sect3>
8177     <title><literal>xmlforest</literal></title>
8178  
8179    <indexterm>
8180     <primary>xmlforest</primary>
8181    </indexterm>
8182  
8183  <synopsis>
8184  <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8185  </synopsis>
8186  
8187     <para>
8188      The <function>xmlforest</function> expression produces an XML
8189      forest (sequence) of elements using the given names and content.
8190     </para>
8191
8192     <para>
8193      Examples:
8194 <screen><![CDATA[
8195 SELECT xmlforest('abc' AS foo, 123 AS bar);
8196
8197           xmlforest
8198 ------------------------------
8199  <foo>abc</foo><bar>123</bar>
8200
8201
8202 SELECT xmlforest(table_name, column_name) FROM information_schema.columns WHERE table_schema = 'pg_catalog';
8203
8204                                          xmlforest
8205 -------------------------------------------------------------------------------------------
8206  <table_name>pg_authid</table_name><column_name>rolname</column_name>
8207  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8208  ...
8209 ]]></screen>
8210
8211      As seen in the second example, the element name can be omitted if
8212      the content value is a column reference, in which case the column
8213      name is used by default.  Otherwise, a name must be specified.
8214     </para>
8215
8216     <para>
8217      Element names that are not valid XML names are escaped as shown
8218      for <function>xmlelement</function> above.  Similarly, content
8219      data is escaped to make valid XML content, unless it is already
8220      of type <type>xml</type>.
8221     </para>
8222
8223     <para>
8224      Note that XML forests are not valid XML documents if they consist
8225      of more than one element.  So it might be useful to wrap
8226      <function>xmlforest</function> expressions in
8227      <function>xmlelement</function>.
8228     </para>
8229    </sect3>
8230  
8231    <sect3>
8232     <title><literal>xmlpi</literal></title>
8233  
8234    <indexterm>
8235     <primary>xmlpi</primary>
8236    </indexterm>
8237  
8238  <synopsis>
8239  <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
8240  </synopsis>
8241  
8242     <para>
8243      The <function>xmlpi</function> expression creates an XML
8244      processing instruction.  The content, if present, must not
8245      contain the character sequence <literal>?&gt;</literal>.
8246     </para>
8247
8248     <para>
8249      Example:
8250 <screen><![CDATA[
8251 SELECT xmlpi(name php, 'echo "hello world";');
8252
8253             xmlpi
8254 -----------------------------
8255  <?php echo "hello world";?>
8256 ]]></screen>
8257     </para>
8258    </sect3>
8259  
8260    <sect3>
8261     <title><literal>xmlroot</literal></title>
8262  
8263    <indexterm>
8264     <primary>xmlroot</primary>
8265    </indexterm>
8266  
8267  <synopsis>
8268  <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable>|no value <optional>, standalone yes|no|no value</optional>)
8269  </synopsis>
8270  
8271     <para>
8272      The <function>xmlroot</function> expression alters the properties
8273      of the root node of an XML value.  If a version is specified,
8274      this replaces the value in the version declaration, if a
8275      standalone value is specified, this replaces the value in the
8276      standalone declaration.
8277     </para>
8278
8279     <para>
8280 <screen><![CDATA[
8281 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'), version '1.0', standalone yes);
8282
8283                 xmlroot
8284 ----------------------------------------
8285  <?xml version="1.0" standalone="yes"?>
8286  <content>abc</content>
8287 ]]></screen>
8288     </para>
8289    </sect3>
8290
8291    <sect3>
8292     <title>XML Predicates</title>
8293
8294     <indexterm>
8295      <primary>IS DOCUMENT</primary>
8296     </indexterm>
8297
8298 <synopsis>
8299 <replaceable>xml</replaceable> IS DOCUMENT
8300 </synopsis>
8301
8302     <para>
8303      The expression <literal>IS DOCUMENT</literal> returns true if the
8304      argument XML value is a proper XML document, false if it is not
8305      (that is, it is a content fragment), or null if the argument is
8306      null.  See <xref linkend="datatype-xml"> about the difference
8307      between documents and content fragments.
8308     </para>
8309    </sect3>
8310   </sect2>
8311
8312   <sect2 id="functions-xml-processing">
8313    <title>Processing XML</title>
8314
8315    <indexterm>
8316     <primary>XPath</primary>
8317    </indexterm>
8318
8319    <para>
8320     To process values of data type <type>xml</type>, PostgreSQL offers
8321     the function <function>xpath</function>, which evaluates XPath 1.0
8322     expressions.
8323    </para>
8324
8325 <synopsis>
8326 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable><optional>, <replaceable>nsarray</replaceable></optional>)
8327 </synopsis>
8328
8329    <para>
8330     The function <function>xpath</function> evaluates the XPath
8331     expression <replaceable>xpath</replaceable> against the XML value
8332     <replaceable>xml</replaceable>.  It returns an array of XML values
8333     corresponding to the node set produced by the XPath expression.
8334    </para>
8335
8336    <para>
8337     The third argument of the function is an array of namespace
8338     mappings.  This array should be a two-dimensional array with the
8339     length of the second axis being equal to 2 (i.e., it should be an
8340     array of arrays, each of which consists of exactly 2 elements).
8341     The first element of each array entry is the namespace name, the
8342     second the namespace URI.
8343    </para>
8344
8345    <para>
8346     Example:
8347 <screen><![CDATA[
8348 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', ARRAY[ARRAY['my', 'http://example.com']]);
8349
8350  xpath  
8351 --------
8352  {test}
8353 (1 row)
8354 ]]></screen>
8355    </para>
8356   </sect2>
8357
8358   <sect2 id="functions-xml-mapping">
8359    <title>Mapping Tables to XML</title>
8360
8361    <indexterm zone="functions-xml-mapping"> 
8362     <primary>XML export</primary>
8363    </indexterm>
8364
8365    <para>
8366     The following functions map the contents of relational tables to
8367     XML values.  They can be thought of as XML export functionality.
8368 <synopsis>
8369 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8370 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
8371 cursor_to_xml(cursor refcursor, count int, nulls boolean, tableforest boolean, targetns text)
8372 </synopsis>
8373     The return type of each function is <type>xml</type>.
8374    </para>
8375
8376    <para>
8377     <function>table_to_xml</function> maps the content of the named
8378     table, passed as parameter <parameter>tbl</parameter>.  The
8379     <type>regclass</type> type accepts strings identifying tables using the
8380     usual notation, including optional schema qualifications and
8381     double quotes.  <function>query_to_xml</function> executes the
8382     query whose text is passed as parameter
8383     <parameter>query</parameter> and maps the result set.
8384     <function>cursor_to_xml</function> fetches the indicated number of
8385     rows from the cursor specified by the parameter
8386     <parameter>cursor</parameter>.  This variant is recommendable if
8387     large tables have to be mapped, because the result value is built
8388     up in memory by each function.
8389    </para>
8390
8391    <para>
8392     If <parameter>tableforest</parameter> is false, then the resulting
8393     XML document looks like this:
8394 <screen><![CDATA[
8395 <tablename>
8396   <row>
8397     <columnname1>data</columnname1>
8398     <columnname2>data</columnname2>
8399   </row>
8400
8401   <row>
8402     ...
8403   </row>
8404
8405   ...
8406 </tablename>
8407 ]]></screen>
8408
8409     If <parameter>tableforest</parameter> is true, the result is an
8410     XML content fragment that looks like this:
8411 <screen><![CDATA[
8412 <tablename>
8413   <columnname1>data</columnname1>
8414   <columnname2>data</columnname2>
8415 </tablename>
8416
8417 <tablename>
8418   ...
8419 </tablename>
8420
8421 ...
8422 ]]></screen>
8423
8424     If no table name is available, that is, when mapping a query or a
8425     cursor, the string <literal>table</literal> is used in the first
8426     format, <literal>row</literal> in the second format.
8427    </para>
8428
8429    <para>
8430     The choice between these formats is up to the user.  The first
8431     format is a proper XML document, which will be important in many
8432     applications.  The second format tends to be more useful in the
8433     <function>cursor_to_xml</function> function if the result values are to be
8434     reassembled into one document later on.  The functions for
8435     producing XML content discussed above, in particular
8436     <function>xmlelement</function>, can be used to alter the results
8437     to taste.
8438    </para>
8439
8440    <para>
8441     The data values are mapped in the same way as described for the
8442     function <function>xmlelement</function> above.
8443    </para>
8444
8445    <para>
8446     The parameter <parameter>nulls</parameter> determines whether null
8447     values should be included in the output.  If true, null values in
8448     columns are represented as
8449 <screen><![CDATA[
8450 <columnname xsi:nil="true"/>
8451 ]]></screen>
8452     where <literal>xsi</literal> is the XML namespace prefix for XML
8453     Schema Instance.  An appropriate namespace declaration will be
8454     added to the result value.  If false, columns containing null
8455     values are simply omitted from the output.
8456    </para>
8457
8458    <para>
8459     The parameter <parameter>targetns</parameter> specifies the
8460     desired XML namespace of the result.  If no particular namespace
8461     is wanted, an empty string should be passed.
8462    </para>
8463
8464    <para>
8465     The following functions return XML Schema documents describing the
8466     mappings made by the data mappings produced by the corresponding
8467     functions above.
8468 <synopsis>
8469 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8470 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8471 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
8472 </synopsis>
8473     It is essential that the same parameters are passed in order to
8474     obtain matching XML data mappings and XML Schema documents.
8475    </para>
8476
8477    <para>
8478     The following functions produce XML data mappings and the
8479     corresponding XML Schema in one document (or forest), linked
8480     together.  They can be useful where self-contained and
8481     self-describing results are wanted.
8482 <synopsis>
8483 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8484 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8485 </synopsis>
8486    </para>
8487
8488    <para>
8489     In addition, the following functions are available to produce
8490     analogous mappings of entire schemas or the entire current
8491     database.
8492 <synopsis>
8493 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
8494 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8495 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8496
8497 database_to_xml(nulls boolean, tableforest boolean, targetns text)
8498 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
8499 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
8500 </synopsis>
8501
8502     Note that these potentially produce a lot of data, which needs to
8503     be built up in memory.  When requesting content mappings of large
8504     schemas or databases, it may be worthwhile to consider mapping the
8505     tables separately instead, possibly even through a cursor.
8506    </para>
8507
8508    <para>
8509     The result of a schema content mapping looks like this:
8510
8511 <screen><![CDATA[
8512 <schemaname>
8513
8514 table1-mapping
8515
8516 table2-mapping
8517
8518 ...
8519
8520 </schemaname>]]></screen>
8521
8522     where the format of a table mapping depends on the
8523     <parameter>tableforest</parameter> parameter as explained above.
8524    </para>
8525
8526    <para>
8527     The result of a database content mapping looks like this:
8528
8529 <screen><![CDATA[
8530 <dbname>
8531
8532 <schema1name>
8533   ...
8534 </schema1name>
8535
8536 <schema2name>
8537   ...
8538 </schema2name>
8539
8540 ...
8541
8542 </dbname>]]></screen>
8543
8544     where the schema mapping is as above.
8545    </para>
8546
8547    <para>
8548     As an example for using the output produced by these functions,
8549     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
8550     converts the output of
8551     <function>table_to_xml_and_xmlschema</function> to an HTML
8552     document containing a tabular rendition of the table data.  In a
8553     similar manner, the result data of these functions can be
8554     converted into other XML-based formats.
8555    </para>
8556
8557    <figure id="xslt-xml-html">
8558     <title>XSLT stylesheet for converting SQL/XML output to HTML</title>
8559 <programlisting><![CDATA[
8560 <?xml version="1.0"?>
8561 <xsl:stylesheet version="1.0"
8562     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
8563     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
8564     xmlns="http://www.w3.org/1999/xhtml"
8565 >
8566
8567   <xsl:output method="xml"
8568       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
8569       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
8570       indent="yes"/>
8571
8572   <xsl:template match="/*">
8573     <xsl:variable name="schema" select="//xsd:schema"/>
8574     <xsl:variable name="tabletypename"
8575                   select="$schema/xsd:element[@name=name(current())]/@type"/>
8576     <xsl:variable name="rowtypename"
8577                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
8578
8579     <html>
8580       <head>
8581         <title><xsl:value-of select="name(current())"/></title>
8582       </head>
8583       <body>
8584         <table>
8585           <tr>
8586             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
8587               <th><xsl:value-of select="."/></th>
8588             </xsl:for-each>
8589           </tr>
8590
8591           <xsl:for-each select="row">
8592             <tr>
8593               <xsl:for-each select="*">
8594                 <td><xsl:value-of select="."/></td>
8595               </xsl:for-each>
8596             </tr>
8597           </xsl:for-each>
8598         </table>
8599       </body>
8600     </html>
8601   </xsl:template>
8602
8603 </xsl:stylesheet>
8604 ]]></programlisting>
8605    </figure>
8606   </sect2>
8607  </sect1>
8608
8609
8610  <sect1 id="functions-sequence">
8611   <title>Sequence Manipulation Functions</title>
8612
8613   <indexterm>
8614    <primary>sequence</primary>
8615   </indexterm>
8616   <indexterm>
8617    <primary>nextval</primary>
8618   </indexterm>
8619   <indexterm>
8620    <primary>currval</primary>
8621   </indexterm>
8622   <indexterm>
8623    <primary>lastval</primary>
8624   </indexterm>
8625   <indexterm>
8626    <primary>setval</primary>
8627   </indexterm>
8628
8629   <para>
8630    This section describes <productname>PostgreSQL</productname>'s
8631    functions for operating on <firstterm>sequence objects</firstterm>.
8632    Sequence objects (also called sequence generators or just
8633    sequences) are special single-row tables created with <xref
8634    linkend="sql-createsequence" endterm="sql-createsequence-title">.
8635    A sequence object is usually used to generate unique identifiers
8636    for rows of a table.  The sequence functions, listed in <xref
8637    linkend="functions-sequence-table">, provide simple, multiuser-safe
8638    methods for obtaining successive sequence values from sequence
8639    objects.
8640   </para>
8641
8642    <table id="functions-sequence-table">
8643     <title>Sequence Functions</title>
8644     <tgroup cols="3">
8645      <thead>
8646       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
8647      </thead>
8648
8649      <tbody>
8650       <row>
8651         <entry><literal><function>currval</function>(<type>regclass</type>)</literal></entry>
8652         <entry><type>bigint</type></entry>
8653         <entry>Return value most recently obtained with
8654         <function>nextval</function> for specified sequence</entry>
8655       </row>
8656       <row>
8657         <entry><literal><function>lastval</function>()</literal></entry>
8658         <entry><type>bigint</type></entry>
8659         <entry>Return value most recently obtained with
8660         <function>nextval</function> for any sequence</entry>
8661       </row>
8662       <row>
8663         <entry><literal><function>nextval</function>(<type>regclass</type>)</literal></entry>
8664         <entry><type>bigint</type></entry>
8665         <entry>Advance sequence and return new value</entry>
8666       </row>
8667       <row>
8668         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>)</literal></entry>
8669         <entry><type>bigint</type></entry>
8670         <entry>Set sequence's current value</entry>
8671       </row>
8672       <row>
8673         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</literal></entry>
8674         <entry><type>bigint</type></entry>
8675         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
8676       </row>
8677      </tbody>
8678     </tgroup>
8679    </table>
8680
8681   <para>
8682    The sequence to be operated on by a sequence-function call is specified by
8683    a <type>regclass</> argument, which is just the OID of the sequence in the
8684    <structname>pg_class</> system catalog.  You do not have to look up the
8685    OID by hand, however, since the <type>regclass</> data type's input
8686    converter will do the work for you.  Just write the sequence name enclosed
8687    in single quotes, so that it looks like a literal constant.  To
8688    achieve some compatibility with the handling of ordinary
8689    <acronym>SQL</acronym> names, the string will be converted to lowercase
8690    unless it contains double quotes around the sequence name.  Thus:
8691 <programlisting>
8692 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
8693 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
8694 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
8695 </programlisting>
8696    The sequence name can be schema-qualified if necessary:
8697 <programlisting>
8698 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
8699 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
8700 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
8701 </programlisting>
8702    See <xref linkend="datatype-oid"> for more information about
8703    <type>regclass</>.
8704   </para>
8705
8706   <note>
8707    <para>
8708     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
8709     sequence functions were of type <type>text</>, not <type>regclass</>, and
8710     the above-described conversion from a text string to an OID value would
8711     happen at run time during each call.  For backwards compatibility, this
8712     facility still exists, but internally it is now handled as an implicit
8713     coercion from <type>text</> to <type>regclass</> before the function is
8714     invoked.
8715    </para>
8716
8717    <para>
8718     When you write the argument of a sequence function as an unadorned
8719     literal string, it becomes a constant of type <type>regclass</>.
8720     Since this is really just an OID, it will track the originally
8721     identified sequence despite later renaming, schema reassignment,
8722     etc.  This <quote>early binding</> behavior is usually desirable for
8723     sequence references in column defaults and views.  But sometimes you will
8724     want <quote>late binding</> where the sequence reference is resolved
8725     at run time.  To get late-binding behavior, force the constant to be
8726     stored as a <type>text</> constant instead of <type>regclass</>:
8727 <programlisting>
8728 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
8729 </programlisting>
8730     Note that late binding was the only behavior supported in
8731     <productname>PostgreSQL</productname> releases before 8.1, so you
8732     might need to do this to preserve the semantics of old applications.
8733    </para>
8734
8735    <para>
8736     Of course, the argument of a sequence function can be an expression
8737     as well as a constant.  If it is a text expression then the implicit
8738     coercion will result in a run-time lookup.
8739    </para>
8740   </note>
8741
8742   <para>
8743    The available sequence functions are:
8744
8745     <variablelist>
8746      <varlistentry>
8747       <term><function>nextval</function></term>
8748       <listitem>
8749        <para>
8750         Advance the sequence object to its next value and return that
8751         value.  This is done atomically: even if multiple sessions
8752         execute <function>nextval</function> concurrently, each will safely receive
8753         a distinct sequence value.
8754        </para>
8755       </listitem>
8756      </varlistentry>
8757
8758      <varlistentry>
8759       <term><function>currval</function></term>
8760       <listitem>
8761        <para>
8762         Return the value most recently obtained by <function>nextval</function>
8763         for this sequence in the current session.  (An error is
8764         reported if <function>nextval</function> has never been called for this
8765         sequence in this session.)  Notice that because this is returning
8766         a session-local value, it gives a predictable answer whether or not
8767         other sessions have executed <function>nextval</function> since the
8768         current session did.
8769        </para>
8770       </listitem>
8771      </varlistentry>
8772
8773      <varlistentry>
8774       <term><function>lastval</function></term>
8775       <listitem>
8776        <para>
8777         Return the value most recently returned by
8778         <function>nextval</> in the current session. This function is
8779         identical to <function>currval</function>, except that instead
8780         of taking the sequence name as an argument it fetches the
8781         value of the last sequence that <function>nextval</function>
8782         was used on in the current session. It is an error to call
8783         <function>lastval</function> if <function>nextval</function>
8784         has not yet been called in the current session.
8785        </para>
8786       </listitem>
8787      </varlistentry>
8788
8789      <varlistentry>
8790       <term><function>setval</function></term>
8791       <listitem>
8792        <para>
8793         Reset the sequence object's counter value.  The two-parameter
8794         form sets the sequence's <literal>last_value</literal> field to the
8795         specified value and sets its <literal>is_called</literal> field to
8796         <literal>true</literal>, meaning that the next
8797         <function>nextval</function> will advance the sequence before
8798         returning a value.  The value reported by <function>currval</> is
8799         also set to the specified value.  In the three-parameter form,
8800         <literal>is_called</literal> can be set either <literal>true</literal>
8801         or <literal>false</literal>.  <literal>true</> has the same effect as
8802         the two-parameter form. If it's set to <literal>false</literal>, the
8803         next <function>nextval</function> will return exactly the specified
8804         value, and sequence advancement commences with the following
8805         <function>nextval</function>.  Furthermore, the value reported by
8806         <function>currval</> is not changed in this case (this is a change
8807         from pre-8.3 behavior).  For example,
8808
8809 <screen>
8810 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
8811 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
8812 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
8813 </screen>
8814
8815         The result returned by <function>setval</function> is just the value of its
8816         second argument.
8817        </para>
8818       </listitem>
8819      </varlistentry>
8820     </variablelist>
8821   </para>
8822
8823   <para>
8824    If a sequence object has been created with default parameters,
8825    <function>nextval</function> calls on it will return successive values
8826    beginning with 1.  Other behaviors can be obtained by using
8827    special parameters in the <xref linkend="sql-createsequence" endterm="sql-createsequence-title"> command;
8828    see its command reference page for more information.
8829   </para>
8830
8831   <important>
8832    <para>
8833     To avoid blocking of concurrent transactions that obtain numbers from the
8834     same sequence, a <function>nextval</function> operation is never rolled back;
8835     that is, once a value has been fetched it is considered used, even if the
8836     transaction that did the <function>nextval</function> later aborts.  This means
8837     that aborted transactions might leave unused <quote>holes</quote> in the
8838     sequence of assigned values.  <function>setval</function> operations are never
8839     rolled back, either.
8840    </para>
8841   </important>
8842
8843  </sect1>
8844
8845
8846  <sect1 id="functions-conditional">
8847   <title>Conditional Expressions</title>
8848
8849   <indexterm>
8850    <primary>CASE</primary>
8851   </indexterm>
8852
8853   <indexterm>
8854    <primary>conditional expression</primary>
8855   </indexterm>
8856
8857   <para>
8858    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
8859    available in <productname>PostgreSQL</productname>.
8860   </para>
8861
8862   <tip>
8863    <para>
8864     If your needs go beyond the capabilities of these conditional
8865     expressions you might want to consider writing a stored procedure
8866     in a more expressive programming language.
8867    </para>
8868   </tip>
8869
8870   <sect2>
8871    <title><literal>CASE</></title>
8872
8873   <para>
8874    The <acronym>SQL</acronym> <token>CASE</token> expression is a
8875    generic conditional expression, similar to if/else statements in
8876    other languages:
8877
8878 <synopsis>
8879 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
8880      <optional>WHEN ...</optional>
8881      <optional>ELSE <replaceable>result</replaceable></optional>
8882 END
8883 </synopsis>
8884
8885    <token>CASE</token> clauses can be used wherever
8886    an expression is valid.  <replaceable>condition</replaceable> is an
8887    expression that returns a <type>boolean</type> result.  If the result is true
8888    then the value of the <token>CASE</token> expression is the
8889    <replaceable>result</replaceable> that follows the condition.  If the result is false any
8890    subsequent <token>WHEN</token> clauses are searched in the same
8891    manner.  If no <token>WHEN</token>
8892    <replaceable>condition</replaceable> is true then the value of the
8893    case expression is the <replaceable>result</replaceable> in the
8894    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
8895    omitted and no condition matches, the result is null.
8896   </para>
8897
8898    <para>
8899     An example:
8900 <screen>
8901 SELECT * FROM test;
8902
8903  a
8904 ---
8905  1
8906  2
8907  3
8908
8909
8910 SELECT a,
8911        CASE WHEN a=1 THEN 'one'
8912             WHEN a=2 THEN 'two'
8913             ELSE 'other'
8914        END
8915     FROM test;
8916
8917  a | case
8918 ---+-------
8919  1 | one
8920  2 | two
8921  3 | other
8922 </screen>
8923    </para>
8924
8925   <para>
8926    The data types of all the <replaceable>result</replaceable>
8927    expressions must be convertible to a single output type.
8928    See <xref linkend="typeconv-union-case"> for more detail.
8929   </para>
8930
8931   <para>
8932    The following <quote>simple</quote> <token>CASE</token> expression is a
8933    specialized variant of the general form above:
8934
8935 <synopsis>
8936 CASE <replaceable>expression</replaceable>
8937     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
8938     <optional>WHEN ...</optional>
8939     <optional>ELSE <replaceable>result</replaceable></optional>
8940 END
8941 </synopsis>
8942
8943    The
8944    <replaceable>expression</replaceable> is computed and compared to
8945    all the <replaceable>value</replaceable> specifications in the
8946    <token>WHEN</token> clauses until one is found that is equal.  If
8947    no match is found, the <replaceable>result</replaceable> in the
8948    <token>ELSE</token> clause (or a null value) is returned.  This is similar
8949    to the <function>switch</function> statement in C.
8950   </para>
8951
8952    <para>
8953     The example above can be written using the simple
8954     <token>CASE</token> syntax:
8955 <screen>
8956 SELECT a,
8957        CASE a WHEN 1 THEN 'one'
8958               WHEN 2 THEN 'two'
8959               ELSE 'other'
8960        END
8961     FROM test;
8962
8963  a | case
8964 ---+-------
8965  1 | one
8966  2 | two
8967  3 | other
8968 </screen>
8969    </para>
8970
8971    <para>
8972     A <token>CASE</token> expression does not evaluate any subexpressions
8973     that are not needed to determine the result.  For example, this is a
8974     possible way of avoiding a division-by-zero failure:
8975 <programlisting>
8976 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
8977 </programlisting>
8978    </para>
8979   </sect2>
8980
8981   <sect2>
8982    <title><literal>COALESCE</></title>
8983
8984   <indexterm>
8985    <primary>COALESCE</primary>
8986   </indexterm>
8987
8988   <indexterm>
8989    <primary>NVL</primary>
8990   </indexterm>
8991
8992   <indexterm>
8993    <primary>IFNULL</primary>
8994   </indexterm>
8995
8996 <synopsis>
8997 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
8998 </synopsis>
8999
9000   <para>
9001    The <function>COALESCE</function> function returns the first of its
9002    arguments that is not null.  Null is returned only if all arguments
9003    are null.  It is often used to substitute a default value for 
9004    null values when data is retrieved for display, for example:
9005 <programlisting>
9006 SELECT COALESCE(description, short_description, '(none)') ...
9007 </programlisting>
9008   </para>
9009
9010    <para>
9011     Like a <token>CASE</token> expression, <function>COALESCE</function> will
9012     not evaluate arguments that are not needed to determine the result;
9013     that is, arguments to the right of the first non-null argument are
9014     not evaluated.  This SQL-standard function provides capabilities similar
9015     to <function>NVL</> and <function>IFNULL</>, which are used in some other
9016     database systems.
9017    </para>
9018   </sect2>
9019
9020   <sect2>
9021    <title><literal>NULLIF</></title>
9022
9023   <indexterm>
9024    <primary>NULLIF</primary>
9025   </indexterm>
9026
9027 <synopsis>
9028 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
9029 </synopsis>
9030
9031   <para>
9032    The <function>NULLIF</function> function returns a null value if
9033    <replaceable>value1</replaceable> and <replaceable>value2</replaceable>
9034    are equal;  otherwise it returns <replaceable>value1</replaceable>.
9035    This can be used to perform the inverse operation of the
9036    <function>COALESCE</function> example given above:
9037 <programlisting>
9038 SELECT NULLIF(value, '(none)') ...
9039 </programlisting>
9040   </para>
9041   <para>
9042    If <replaceable>value1</replaceable> is <literal>(none)</>, return a null,
9043    otherwise return <replaceable>value1</replaceable>.
9044   </para>
9045
9046   </sect2>
9047
9048   <sect2>
9049    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
9050
9051   <indexterm>
9052    <primary>GREATEST</primary>
9053   </indexterm>
9054   <indexterm>
9055    <primary>LEAST</primary>
9056   </indexterm>
9057
9058 <synopsis>
9059 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9060 </synopsis>
9061 <synopsis>
9062 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9063 </synopsis>
9064
9065    <para>
9066     The <function>GREATEST</> and <function>LEAST</> functions select the
9067     largest or smallest value from a list of any number of expressions.
9068     The expressions must all be convertible to a common data type, which
9069     will be the type of the result
9070     (see <xref linkend="typeconv-union-case"> for details).  NULL values
9071     in the list are ignored.  The result will be NULL only if all the
9072     expressions evaluate to NULL.
9073    </para>
9074
9075    <para>
9076     Note that <function>GREATEST</> and <function>LEAST</> are not in
9077     the SQL standard, but are a common extension.  Some other databases
9078     make them return NULL if any argument is NULL, rather than only when
9079     all are NULL.
9080    </para>
9081   </sect2>
9082  </sect1>
9083
9084
9085  <sect1 id="functions-array">
9086   <title>Array Functions and Operators</title>
9087
9088   <para>
9089    <xref linkend="array-operators-table"> shows the operators
9090    available for <type>array</type> types.
9091   </para>
9092
9093     <table id="array-operators-table">
9094      <title><type>array</type> Operators</title>
9095      <tgroup cols="4">
9096       <thead>
9097        <row>
9098         <entry>Operator</entry>
9099         <entry>Description</entry>
9100         <entry>Example</entry>
9101         <entry>Result</entry>
9102        </row>
9103       </thead>
9104       <tbody>
9105        <row>
9106         <entry> <literal>=</literal> </entry>
9107         <entry>equal</entry>
9108         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
9109         <entry><literal>t</literal></entry>
9110        </row>
9111
9112        <row>
9113         <entry> <literal>&lt;&gt;</literal> </entry>
9114         <entry>not equal</entry>
9115         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
9116         <entry><literal>t</literal></entry>
9117        </row>
9118
9119        <row>
9120         <entry> <literal>&lt;</literal> </entry>
9121         <entry>less than</entry>
9122         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
9123         <entry><literal>t</literal></entry>
9124        </row>
9125
9126        <row>
9127         <entry> <literal>&gt;</literal> </entry>
9128         <entry>greater than</entry>
9129         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
9130         <entry><literal>t</literal></entry>
9131        </row>
9132
9133        <row>
9134         <entry> <literal>&lt;=</literal> </entry>
9135         <entry>less than or equal</entry>
9136         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
9137         <entry><literal>t</literal></entry>
9138        </row>
9139
9140        <row>
9141         <entry> <literal>&gt;=</literal> </entry>
9142         <entry>greater than or equal</entry>
9143         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
9144         <entry><literal>t</literal></entry>
9145        </row>
9146
9147        <row>
9148         <entry> <literal>@&gt;</literal> </entry>
9149         <entry>contains</entry>
9150         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
9151         <entry><literal>t</literal></entry>
9152        </row>
9153
9154        <row>
9155         <entry> <literal>&lt;@</literal> </entry>
9156         <entry>is contained by</entry>
9157         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
9158         <entry><literal>t</literal></entry>
9159        </row>
9160
9161        <row>
9162         <entry> <literal>&amp;&amp;</literal> </entry>
9163         <entry>overlap (have elements in common)</entry>
9164         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
9165         <entry><literal>t</literal></entry>
9166        </row>
9167
9168        <row>
9169         <entry> <literal>||</literal> </entry>
9170         <entry>array-to-array concatenation</entry>
9171         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
9172         <entry><literal>{1,2,3,4,5,6}</literal></entry>
9173        </row>
9174
9175        <row>
9176         <entry> <literal>||</literal> </entry>
9177         <entry>array-to-array concatenation</entry>
9178         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
9179         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
9180        </row>
9181
9182        <row>
9183         <entry> <literal>||</literal> </entry>
9184         <entry>element-to-array concatenation</entry>
9185         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
9186         <entry><literal>{3,4,5,6}</literal></entry>
9187        </row>
9188
9189        <row>
9190         <entry> <literal>||</literal> </entry>
9191         <entry>array-to-element concatenation</entry>
9192         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
9193         <entry><literal>{4,5,6,7}</literal></entry>
9194        </row>
9195       </tbody>
9196      </tgroup>
9197     </table>
9198
9199   <para>
9200    Array comparisons compare the array contents element-by-element,
9201    using the default B-Tree comparison function for the element data type.
9202    In multidimensional arrays the elements are visited in row-major order
9203    (last subscript varies most rapidly).
9204    If the contents of two arrays are equal but the dimensionality is
9205    different, the first difference in the dimensionality information
9206    determines the sort order.  (This is a change from versions of
9207    <productname>PostgreSQL</> prior to 8.2: older versions would claim
9208    that two arrays with the same contents were equal, even if the
9209    number of dimensions or subscript ranges were different.)
9210   </para>
9211
9212   <para>
9213    See <xref linkend="arrays"> for more details about array operator
9214    behavior.
9215   </para>
9216
9217   <para>
9218    <xref linkend="array-functions-table"> shows the functions
9219    available for use with array types. See <xref linkend="arrays">
9220    for more discussion and examples of the use of these functions.
9221   </para>
9222
9223     <table id="array-functions-table">
9224      <title><type>array</type> Functions</title>
9225      <tgroup cols="5">
9226       <thead>
9227        <row>
9228         <entry>Function</entry>
9229         <entry>Return Type</entry>
9230         <entry>Description</entry>
9231         <entry>Example</entry>
9232         <entry>Result</entry>
9233        </row>
9234       </thead>
9235       <tbody>
9236        <row>
9237         <entry>
9238      <literal>
9239       <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
9240      </literal>
9241     </entry>
9242         <entry><type>anyarray</type></entry>
9243         <entry>append an element to the end of an array</entry>
9244         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
9245         <entry><literal>{1,2,3}</literal></entry>
9246        </row>
9247        <row>
9248         <entry>
9249      <literal>
9250       <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
9251      </literal>
9252     </entry>
9253         <entry><type>anyarray</type></entry>
9254         <entry>concatenate two arrays</entry>
9255         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
9256         <entry><literal>{1,2,3,4,5}</literal></entry>
9257        </row>
9258        <row>
9259         <entry>
9260      <literal>
9261       <function>array_dims</function>(<type>anyarray</type>)
9262      </literal>
9263     </entry>
9264         <entry><type>text</type></entry>
9265         <entry>returns a text representation of array's dimensions</entry>
9266         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9267         <entry><literal>[1:2][1:3]</literal></entry>
9268        </row>
9269        <row>
9270         <entry>
9271      <literal>
9272       <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
9273      </literal>
9274     </entry>
9275         <entry><type>int</type></entry>
9276         <entry>returns lower bound of the requested array dimension</entry>
9277         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
9278         <entry><literal>0</literal></entry>
9279        </row>
9280        <row>
9281         <entry>
9282      <literal>
9283       <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
9284      </literal>
9285     </entry>
9286         <entry><type>anyarray</type></entry>
9287         <entry>append an element to the beginning of an array</entry>
9288         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
9289         <entry><literal>{1,2,3}</literal></entry>
9290        </row>
9291        <row>
9292         <entry>
9293      <literal>
9294       <function>array_to_string</function>(<type>anyarray</type>, <type>text</type>)
9295      </literal>
9296     </entry>
9297         <entry><type>text</type></entry>
9298         <entry>concatenates array elements using provided delimiter</entry>
9299         <entry><literal>array_to_string(ARRAY[1, 2, 3], '~^~')</literal></entry>
9300         <entry><literal>1~^~2~^~3</literal></entry>
9301        </row>
9302        <row>
9303         <entry>
9304      <literal>
9305       <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
9306      </literal>
9307     </entry>
9308         <entry><type>int</type></entry>
9309         <entry>returns upper bound of the requested array dimension</entry>
9310         <entry><literal>array_upper(ARRAY[1,2,3,4], 1)</literal></entry>
9311         <entry><literal>4</literal></entry>
9312        </row>
9313        <row>
9314         <entry>
9315      <literal>
9316       <function>string_to_array</function>(<type>text</type>, <type>text</type>)
9317      </literal>
9318     </entry>
9319         <entry><type>text[]</type></entry>
9320         <entry>splits string into array elements using provided delimiter</entry>
9321         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~')</literal></entry>
9322         <entry><literal>{xx,yy,zz}</literal></entry>
9323        </row>
9324       </tbody>
9325      </tgroup>
9326     </table>
9327   </sect1>
9328
9329  <sect1 id="functions-aggregate">
9330   <title>Aggregate Functions</title>
9331
9332   <indexterm zone="functions-aggregate">
9333    <primary>aggregate function</primary>
9334    <secondary>built-in</secondary>
9335   </indexterm>
9336
9337   <para>
9338    <firstterm>Aggregate functions</firstterm> compute a single result
9339    value from a set of input values.  The built-in aggregate functions
9340    are listed in
9341    <xref linkend="functions-aggregate-table"> and
9342    <xref linkend="functions-aggregate-statistics-table">.
9343    The special syntax considerations for aggregate
9344    functions are explained in <xref linkend="syntax-aggregates">.
9345    Consult <xref linkend="tutorial-agg"> for additional introductory
9346    information.
9347   </para>
9348
9349   <table id="functions-aggregate-table">
9350    <title>General-Purpose Aggregate Functions</title>
9351
9352    <tgroup cols="4">
9353     <thead>
9354      <row>
9355       <entry>Function</entry>
9356       <entry>Argument Type</entry>
9357       <entry>Return Type</entry>
9358       <entry>Description</entry>
9359      </row>
9360     </thead>
9361
9362     <tbody>
9363      <row>
9364       <entry>
9365        <indexterm>
9366         <primary>average</primary>
9367        </indexterm>
9368        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
9369       </entry>
9370       <entry>
9371        <type>smallint</type>, <type>int</type>,
9372        <type>bigint</type>, <type>real</type>, <type>double
9373        precision</type>, <type>numeric</type>, or <type>interval</type>
9374       </entry>
9375       <entry>
9376        <type>numeric</type> for any integer type argument,
9377        <type>double precision</type> for a floating-point argument,
9378        otherwise the same as the argument data type
9379       </entry>
9380       <entry>the average (arithmetic mean) of all input values</entry>
9381      </row>
9382
9383      <row>
9384       <entry>
9385        <indexterm>
9386         <primary>bit_and</primary>
9387        </indexterm>
9388        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
9389       </entry>
9390       <entry>
9391        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9392        <type>bit</type>
9393       </entry>
9394       <entry>
9395         same as argument data type
9396       </entry>
9397       <entry>the bitwise AND of all non-null input values, or null if none</entry>
9398      </row>
9399
9400      <row>
9401       <entry>
9402        <indexterm>
9403         <primary>bit_or</primary>
9404        </indexterm>
9405        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
9406       </entry>
9407       <entry>
9408        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9409        <type>bit</type>
9410       </entry>
9411       <entry>
9412         same as argument data type
9413       </entry>
9414       <entry>the bitwise OR of all non-null input values, or null if none</entry>
9415      </row>
9416
9417      <row>
9418       <entry>
9419        <indexterm>
9420         <primary>bool_and</primary>
9421        </indexterm>
9422        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
9423       </entry>
9424       <entry>
9425        <type>bool</type>
9426       </entry>
9427       <entry>
9428        <type>bool</type>
9429       </entry>
9430       <entry>true if all input values are true, otherwise false</entry>
9431      </row>
9432
9433      <row>
9434       <entry>
9435        <indexterm>
9436         <primary>bool_or</primary>
9437        </indexterm>
9438        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
9439       </entry>
9440       <entry>
9441        <type>bool</type>
9442       </entry>
9443       <entry>
9444        <type>bool</type>
9445       </entry>
9446       <entry>true if at least one input value is true, otherwise false</entry>
9447      </row>
9448
9449      <row>
9450       <entry><function>count(*)</function></entry>
9451       <entry></entry>
9452       <entry><type>bigint</type></entry>
9453       <entry>number of input rows</entry>
9454      </row>
9455
9456      <row>
9457       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
9458       <entry>any</entry>
9459       <entry><type>bigint</type></entry>
9460       <entry>
9461        number of input rows for which the value of <replaceable
9462        class="parameter">expression</replaceable> is not null
9463       </entry>
9464      </row>
9465
9466      <row>
9467       <entry>
9468        <indexterm>
9469         <primary>every</primary>
9470        </indexterm>
9471        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
9472       </entry>
9473       <entry>
9474        <type>bool</type>
9475       </entry>
9476       <entry>
9477        <type>bool</type>
9478       </entry>
9479       <entry>equivalent to <function>bool_and</function></entry>
9480      </row>
9481
9482      <row>
9483       <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
9484       <entry>any array, numeric, string, or date/time type</entry>
9485       <entry>same as argument type</entry>
9486       <entry>
9487        maximum value of <replaceable
9488        class="parameter">expression</replaceable> across all input
9489        values
9490       </entry>
9491      </row>
9492
9493      <row>
9494       <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
9495       <entry>any array, numeric, string, or date/time type</entry>
9496       <entry>same as argument type</entry>
9497       <entry>
9498        minimum value of <replaceable
9499        class="parameter">expression</replaceable> across all input
9500        values
9501       </entry>
9502      </row>
9503
9504      <row>
9505       <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></entry>
9506       <entry>
9507        <type>smallint</type>, <type>int</type>,
9508        <type>bigint</type>, <type>real</type>, <type>double
9509        precision</type>, <type>numeric</type>, or
9510        <type>interval</type>
9511       </entry>
9512       <entry>
9513        <type>bigint</type> for <type>smallint</type> or
9514        <type>int</type> arguments, <type>numeric</type> for
9515        <type>bigint</type> arguments, <type>double precision</type>
9516        for floating-point arguments, otherwise the same as the
9517        argument data type
9518       </entry>
9519       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
9520      </row>
9521     </tbody>
9522    </tgroup>
9523   </table>
9524
9525   <para>
9526    It should be noted that except for <function>count</function>,
9527    these functions return a null value when no rows are selected.  In
9528    particular, <function>sum</function> of no rows returns null, not
9529    zero as one might expect.  The <function>coalesce</function> function can be
9530    used to substitute zero for null when necessary.
9531   </para>
9532
9533   <note>
9534     <indexterm>
9535       <primary>ANY</primary>
9536     </indexterm>
9537     <indexterm>
9538       <primary>SOME</primary>
9539     </indexterm>
9540     <para>
9541       Boolean aggregates <function>bool_and</function> and 
9542       <function>bool_or</function> correspond to standard SQL aggregates
9543       <function>every</function> and <function>any</function> or
9544       <function>some</function>. 
9545       As for <function>any</function> and <function>some</function>, 
9546       it seems that there is an ambiguity built into the standard syntax:
9547 <programlisting>
9548 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
9549 </programlisting>
9550       Here <function>ANY</function> can be considered both as leading
9551       to a subquery or as an aggregate if the select expression returns 1 row.
9552       Thus the standard name cannot be given to these aggregates.
9553     </para>
9554   </note>
9555
9556   <note>
9557    <para>
9558     Users accustomed to working with other SQL database management
9559     systems might be surprised by the performance of the
9560     <function>count</function> aggregate when it is applied to the
9561     entire table. A query like:
9562 <programlisting>
9563 SELECT count(*) FROM sometable;
9564 </programlisting>
9565     will be executed by <productname>PostgreSQL</productname> using a
9566     sequential scan of the entire table.
9567    </para>
9568   </note>
9569
9570
9571   <para>
9572    <xref linkend="functions-aggregate-statistics-table"> shows
9573    aggregate functions typically used in statistical analysis.
9574    (These are separated out merely to avoid cluttering the listing
9575    of more-commonly-used aggregates.)  Where the description mentions
9576    <replaceable class="parameter">N</replaceable>, it means the
9577    number of input rows for which all the input expressions are non-null.
9578    In all cases, null is returned if the computation is meaningless,
9579    for example when <replaceable class="parameter">N</replaceable> is zero.
9580   </para>
9581
9582   <indexterm>
9583    <primary>statistics</primary>
9584   </indexterm>
9585   <indexterm>
9586    <primary>linear regression</primary>
9587   </indexterm>
9588
9589   <table id="functions-aggregate-statistics-table">
9590    <title>Aggregate Functions for Statistics</title>
9591
9592    <tgroup cols="4">
9593     <thead>
9594      <row>
9595       <entry>Function</entry>
9596       <entry>Argument Type</entry>
9597       <entry>Return Type</entry>
9598       <entry>Description</entry>
9599      </row>
9600     </thead>
9601
9602     <tbody>
9603
9604      <row>
9605       <entry>
9606        <indexterm>
9607         <primary>correlation</primary>
9608        </indexterm>
9609        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9610       </entry>
9611       <entry>
9612        <type>double precision</type>
9613       </entry>
9614       <entry>
9615        <type>double precision</type>
9616       </entry>
9617       <entry>correlation coefficient</entry>
9618      </row>
9619
9620      <row>
9621       <entry>
9622        <indexterm>
9623         <primary>covariance</primary>
9624         <secondary>population</secondary>
9625        </indexterm>
9626        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9627       </entry>
9628       <entry>
9629        <type>double precision</type>
9630       </entry>
9631       <entry>
9632        <type>double precision</type>
9633       </entry>
9634       <entry>population covariance</entry>
9635      </row>
9636
9637      <row>
9638       <entry>
9639        <indexterm>
9640         <primary>covariance</primary>
9641         <secondary>sample</secondary>
9642        </indexterm>
9643        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9644       </entry>
9645       <entry>
9646        <type>double precision</type>
9647       </entry>
9648       <entry>
9649        <type>double precision</type>
9650       </entry>
9651       <entry>sample covariance</entry>
9652      </row>
9653
9654      <row>
9655       <entry>
9656        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9657       </entry>
9658       <entry>
9659        <type>double precision</type>
9660       </entry>
9661       <entry>
9662        <type>double precision</type>
9663       </entry>
9664       <entry>average of the independent variable
9665       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9666      </row>
9667
9668      <row>
9669       <entry>
9670        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9671       </entry>
9672       <entry>
9673        <type>double precision</type>
9674       </entry>
9675       <entry>
9676        <type>double precision</type>
9677       </entry>
9678       <entry>average of the dependent variable
9679       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9680      </row>
9681
9682      <row>
9683       <entry>
9684        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9685       </entry>
9686       <entry>
9687        <type>double precision</type>
9688       </entry>
9689       <entry>
9690        <type>bigint</type>
9691       </entry>
9692       <entry>number of input rows in which both expressions are nonnull</entry>
9693      </row>
9694
9695      <row>
9696       <entry>
9697        <indexterm>
9698         <primary>regression intercept</primary>
9699        </indexterm>
9700        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9701       </entry>
9702       <entry>
9703        <type>double precision</type>
9704       </entry>
9705       <entry>
9706        <type>double precision</type>
9707       </entry>
9708       <entry>y-intercept of the least-squares-fit linear equation
9709       determined by the (<replaceable
9710       class="parameter">X</replaceable>, <replaceable
9711       class="parameter">Y</replaceable>) pairs</entry>
9712      </row>
9713
9714      <row>
9715       <entry>
9716        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9717       </entry>
9718       <entry>
9719        <type>double precision</type>
9720       </entry>
9721       <entry>
9722        <type>double precision</type>
9723       </entry>
9724       <entry>square of the correlation coefficient</entry>
9725      </row>
9726
9727      <row>
9728       <entry>
9729        <indexterm>
9730         <primary>regression slope</primary>
9731        </indexterm>
9732        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9733       </entry>
9734       <entry>
9735        <type>double precision</type>
9736       </entry>
9737       <entry>
9738        <type>double precision</type>
9739       </entry>
9740       <entry>slope of the least-squares-fit linear equation determined
9741       by the (<replaceable class="parameter">X</replaceable>,
9742       <replaceable class="parameter">Y</replaceable>) pairs</entry>
9743      </row>
9744
9745      <row>
9746       <entry>
9747        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9748       </entry>
9749       <entry>
9750        <type>double precision</type>
9751       </entry>
9752       <entry>
9753        <type>double precision</type>
9754       </entry>
9755       <entry><literal>sum(<replaceable
9756       class="parameter">X</replaceable>^2) - sum(<replaceable
9757       class="parameter">X</replaceable>)^2/<replaceable
9758       class="parameter">N</replaceable></literal> (<quote>sum of
9759       squares</quote> of the independent variable)</entry>
9760      </row>
9761
9762      <row>
9763       <entry>
9764        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9765       </entry>
9766       <entry>
9767        <type>double precision</type>
9768       </entry>
9769       <entry>
9770        <type>double precision</type>
9771       </entry>
9772       <entry><literal>sum(<replaceable
9773       class="parameter">X</replaceable>*<replaceable
9774       class="parameter">Y</replaceable>) - sum(<replaceable
9775       class="parameter">X</replaceable>) * sum(<replaceable
9776       class="parameter">Y</replaceable>)/<replaceable
9777       class="parameter">N</replaceable></literal> (<quote>sum of
9778       products</quote> of independent times dependent
9779       variable)</entry>
9780      </row>
9781
9782      <row>
9783       <entry>
9784        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9785       </entry>
9786       <entry>
9787        <type>double precision</type>
9788       </entry>
9789       <entry>
9790        <type>double precision</type>
9791       </entry>
9792       <entry><literal>sum(<replaceable
9793       class="parameter">Y</replaceable>^2) - sum(<replaceable
9794       class="parameter">Y</replaceable>)^2/<replaceable
9795       class="parameter">N</replaceable></literal> (<quote>sum of
9796       squares</quote> of the dependent variable)</entry>
9797      </row>
9798
9799      <row>
9800       <entry>
9801        <indexterm>
9802         <primary>standard deviation</primary>
9803        </indexterm>
9804        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
9805       </entry>
9806       <entry>
9807        <type>smallint</type>, <type>int</type>,
9808        <type>bigint</type>, <type>real</type>, <type>double
9809        precision</type>, or <type>numeric</type>
9810       </entry>
9811       <entry>
9812        <type>double precision</type> for floating-point arguments,
9813        otherwise <type>numeric</type>
9814       </entry>
9815       <entry>historical alias for <function>stddev_samp</function></entry>
9816      </row>
9817
9818      <row>
9819       <entry>
9820        <indexterm>
9821         <primary>standard deviation</primary>
9822         <secondary>population</secondary>
9823        </indexterm>
9824        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
9825       </entry>
9826       <entry>
9827        <type>smallint</type>, <type>int</type>,
9828        <type>bigint</type>, <type>real</type>, <type>double
9829        precision</type>, or <type>numeric</type>
9830       </entry>
9831       <entry>
9832        <type>double precision</type> for floating-point arguments,
9833        otherwise <type>numeric</type>
9834       </entry>
9835       <entry>population standard deviation of the input values</entry>
9836      </row>
9837
9838      <row>
9839       <entry>
9840        <indexterm>
9841         <primary>standard deviation</primary>
9842         <secondary>sample</secondary>
9843        </indexterm>
9844        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
9845       </entry>
9846       <entry>
9847        <type>smallint</type>, <type>int</type>,
9848        <type>bigint</type>, <type>real</type>, <type>double
9849        precision</type>, or <type>numeric</type>
9850       </entry>
9851       <entry>
9852        <type>double precision</type> for floating-point arguments,
9853        otherwise <type>numeric</type>
9854       </entry>
9855       <entry>sample standard deviation of the input values</entry>
9856      </row>
9857
9858      <row>
9859       <entry>
9860        <indexterm>
9861         <primary>variance</primary>
9862        </indexterm>
9863        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
9864       </entry>
9865       <entry>
9866        <type>smallint</type>, <type>int</type>,
9867        <type>bigint</type>, <type>real</type>, <type>double
9868        precision</type>, or <type>numeric</type>
9869       </entry>
9870       <entry>
9871        <type>double precision</type> for floating-point arguments,
9872        otherwise <type>numeric</type>
9873       </entry>
9874       <entry>historical alias for <function>var_samp</function></entry>
9875      </row>
9876
9877      <row>
9878       <entry>
9879        <indexterm>
9880         <primary>variance</primary>
9881         <secondary>population</secondary>
9882        </indexterm>
9883        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
9884       </entry>
9885       <entry>
9886        <type>smallint</type>, <type>int</type>,
9887        <type>bigint</type>, <type>real</type>, <type>double
9888        precision</type>, or <type>numeric</type>
9889       </entry>
9890       <entry>
9891        <type>double precision</type> for floating-point arguments,
9892        otherwise <type>numeric</type>
9893       </entry>
9894       <entry>population variance of the input values (square of the population standard deviation)</entry>
9895      </row>
9896
9897      <row>
9898       <entry>
9899        <indexterm>
9900         <primary>variance</primary>
9901         <secondary>sample</secondary>
9902        </indexterm>
9903        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
9904       </entry>
9905       <entry>
9906        <type>smallint</type>, <type>int</type>,
9907        <type>bigint</type>, <type>real</type>, <type>double
9908        precision</type>, or <type>numeric</type>
9909       </entry>
9910       <entry>
9911        <type>double precision</type> for floating-point arguments,
9912        otherwise <type>numeric</type>
9913       </entry>
9914       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
9915      </row>
9916     </tbody>
9917    </tgroup>
9918   </table>
9919
9920  </sect1>
9921
9922
9923  <sect1 id="functions-subquery">
9924   <title>Subquery Expressions</title>
9925
9926   <indexterm>
9927    <primary>EXISTS</primary>
9928   </indexterm>
9929
9930   <indexterm>
9931    <primary>IN</primary>
9932   </indexterm>
9933
9934   <indexterm>
9935    <primary>NOT IN</primary>
9936   </indexterm>
9937
9938   <indexterm>
9939    <primary>ANY</primary>
9940   </indexterm>
9941
9942   <indexterm>
9943    <primary>ALL</primary>
9944   </indexterm>
9945
9946   <indexterm>
9947    <primary>SOME</primary>
9948   </indexterm>
9949
9950   <indexterm>
9951    <primary>subquery</primary>
9952   </indexterm>
9953
9954   <para>
9955    This section describes the <acronym>SQL</acronym>-compliant subquery
9956    expressions available in <productname>PostgreSQL</productname>.
9957    All of the expression forms documented in this section return
9958    Boolean (true/false) results.
9959   </para>
9960
9961   <sect2>
9962    <title><literal>EXISTS</literal></title>
9963
9964 <synopsis>
9965 EXISTS (<replaceable>subquery</replaceable>)
9966 </synopsis>
9967
9968   <para>
9969    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
9970    or <firstterm>subquery</firstterm>.  The
9971    subquery is evaluated to determine whether it returns any rows.
9972    If it returns at least one row, the result of <token>EXISTS</token> is
9973    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token> 
9974    is <quote>false</>.
9975   </para>
9976
9977   <para>
9978    The subquery can refer to variables from the surrounding query,
9979    which will act as constants during any one evaluation of the subquery.
9980   </para>
9981
9982   <para>
9983    The subquery will generally only be executed far enough to determine
9984    whether at least one row is returned, not all the way to completion.
9985    It is unwise to write a subquery that has any side effects (such as
9986    calling sequence functions); whether the side effects occur or not
9987    might be difficult to predict.
9988   </para>
9989
9990   <para>
9991    Since the result depends only on whether any rows are returned,
9992    and not on the contents of those rows, the output list of the
9993    subquery is normally uninteresting.  A common coding convention is
9994    to write all <literal>EXISTS</> tests in the form
9995    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
9996    this rule however, such as subqueries that use <token>INTERSECT</token>.
9997   </para>
9998
9999   <para>
10000    This simple example is like an inner join on <literal>col2</>, but
10001    it produces at most one output row for each <literal>tab1</> row,
10002    even if there are multiple matching <literal>tab2</> rows:
10003 <screen>
10004 SELECT col1 FROM tab1
10005     WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
10006 </screen>
10007   </para>
10008   </sect2>
10009
10010   <sect2>
10011    <title><literal>IN</literal></title>
10012
10013 <synopsis>
10014 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
10015 </synopsis>
10016
10017   <para>
10018    The right-hand side is a parenthesized
10019    subquery, which must return exactly one column.  The left-hand expression
10020    is evaluated and compared to each row of the subquery result.
10021    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10022    The result is <quote>false</> if no equal row is found (including the special
10023    case where the subquery returns no rows).
10024   </para>
10025
10026   <para>
10027    Note that if the left-hand expression yields null, or if there are
10028    no equal right-hand values and at least one right-hand row yields
10029    null, the result of the <token>IN</token> construct will be null, not false.
10030    This is in accordance with SQL's normal rules for Boolean combinations
10031    of null values.
10032   </para>
10033
10034   <para>
10035    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10036    be evaluated completely.
10037   </para>
10038
10039 <synopsis>
10040 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
10041 </synopsis>
10042
10043   <para>
10044    The left-hand side of this form of <token>IN</token> is a row constructor,
10045    as described in <xref linkend="sql-syntax-row-constructors">.
10046    The right-hand side is a parenthesized
10047    subquery, which must return exactly as many columns as there are
10048    expressions in the left-hand row.  The left-hand expressions are
10049    evaluated and compared row-wise to each row of the subquery result.
10050    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10051    The result is <quote>false</> if no equal row is found (including the special
10052    case where the subquery returns no rows).
10053   </para>
10054
10055   <para>
10056    As usual, null values in the rows are combined per
10057    the normal rules of SQL Boolean expressions.  Two rows are considered
10058    equal if all their corresponding members are non-null and equal; the rows
10059    are unequal if any corresponding members are non-null and unequal;
10060    otherwise the result of that row comparison is unknown (null).
10061    If all the per-row results are either unequal or null, with at least one
10062    null, then the result of <token>IN</token> is null.
10063   </para>
10064   </sect2>
10065
10066   <sect2>
10067    <title><literal>NOT IN</literal></title>
10068
10069 <synopsis>
10070 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10071 </synopsis>
10072
10073   <para>
10074    The right-hand side is a parenthesized
10075    subquery, which must return exactly one column.  The left-hand expression
10076    is evaluated and compared to each row of the subquery result.
10077    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10078    are found (including the special case where the subquery returns no rows).
10079    The result is <quote>false</> if any equal row is found.
10080   </para>
10081
10082   <para>
10083    Note that if the left-hand expression yields null, or if there are
10084    no equal right-hand values and at least one right-hand row yields
10085    null, the result of the <token>NOT IN</token> construct will be null, not true.
10086    This is in accordance with SQL's normal rules for Boolean combinations
10087    of null values.
10088   </para>
10089
10090   <para>
10091    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10092    be evaluated completely.
10093   </para>
10094
10095 <synopsis>
10096 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10097 </synopsis>
10098
10099   <para>
10100    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
10101    as described in <xref linkend="sql-syntax-row-constructors">.
10102    The right-hand side is a parenthesized
10103    subquery, which must return exactly as many columns as there are
10104    expressions in the left-hand row.  The left-hand expressions are
10105    evaluated and compared row-wise to each row of the subquery result.
10106    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10107    are found (including the special case where the subquery returns no rows).
10108    The result is <quote>false</> if any equal row is found.
10109   </para>
10110
10111   <para>
10112    As usual, null values in the rows are combined per
10113    the normal rules of SQL Boolean expressions.  Two rows are considered
10114    equal if all their corresponding members are non-null and equal; the rows
10115    are unequal if any corresponding members are non-null and unequal;
10116    otherwise the result of that row comparison is unknown (null).
10117    If all the per-row results are either unequal or null, with at least one
10118    null, then the result of <token>NOT IN</token> is null.
10119   </para>
10120   </sect2>
10121
10122   <sect2>
10123    <title><literal>ANY</literal>/<literal>SOME</literal></title>
10124
10125 <synopsis>
10126 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
10127 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
10128 </synopsis>
10129
10130   <para>
10131    The right-hand side is a parenthesized
10132    subquery, which must return exactly one column.  The left-hand expression
10133    is evaluated and compared to each row of the subquery result using the
10134    given <replaceable>operator</replaceable>, which must yield a Boolean
10135    result.
10136    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10137    The result is <quote>false</> if no true result is found (including the special
10138    case where the subquery returns no rows).
10139   </para>
10140
10141   <para>
10142    <token>SOME</token> is a synonym for <token>ANY</token>.
10143    <token>IN</token> is equivalent to <literal>= ANY</literal>.
10144   </para>
10145
10146   <para>
10147    Note that if there are no successes and at least one right-hand row yields
10148    null for the operator's result, the result of the <token>ANY</token> construct
10149    will be null, not false.
10150    This is in accordance with SQL's normal rules for Boolean combinations
10151    of null values.
10152   </para>
10153
10154   <para>
10155    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10156    be evaluated completely.
10157   </para>
10158
10159 <synopsis>
10160 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
10161 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
10162 </synopsis>
10163
10164   <para>
10165    The left-hand side of this form of <token>ANY</token> is a row constructor,
10166    as described in <xref linkend="sql-syntax-row-constructors">.
10167    The right-hand side is a parenthesized
10168    subquery, which must return exactly as many columns as there are
10169    expressions in the left-hand row.  The left-hand expressions are
10170    evaluated and compared row-wise to each row of the subquery result,
10171    using the given <replaceable>operator</replaceable>.
10172    The result of <token>ANY</token> is <quote>true</> if the comparison
10173    returns true for any subquery row.
10174    The result is <quote>false</> if the comparison returns false for every
10175    subquery row (including the special case where the subquery returns no
10176    rows).
10177    The result is NULL if the comparison does not return true for any row,
10178    and it returns NULL for at least one row.
10179   </para>
10180
10181   <para>
10182    See <xref linkend="row-wise-comparison"> for details about the meaning
10183    of a row-wise comparison.
10184   </para>
10185   </sect2>
10186
10187   <sect2>
10188    <title><literal>ALL</literal></title>
10189
10190 <synopsis>
10191 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10192 </synopsis>
10193
10194   <para>
10195    The right-hand side is a parenthesized
10196    subquery, which must return exactly one column.  The left-hand expression
10197    is evaluated and compared to each row of the subquery result using the
10198    given <replaceable>operator</replaceable>, which must yield a Boolean
10199    result.
10200    The result of <token>ALL</token> is <quote>true</> if all rows yield true
10201    (including the special case where the subquery returns no rows).
10202    The result is <quote>false</> if any false result is found.
10203    The result is NULL if the comparison does not return false for any row,
10204    and it returns NULL for at least one row.
10205   </para>
10206
10207   <para>
10208    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
10209   </para>
10210
10211   <para>
10212    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10213    be evaluated completely.
10214   </para>
10215
10216 <synopsis>
10217 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10218 </synopsis>
10219
10220   <para>
10221    The left-hand side of this form of <token>ALL</token> is a row constructor,
10222    as described in <xref linkend="sql-syntax-row-constructors">.
10223    The right-hand side is a parenthesized
10224    subquery, which must return exactly as many columns as there are
10225    expressions in the left-hand row.  The left-hand expressions are
10226    evaluated and compared row-wise to each row of the subquery result,
10227    using the given <replaceable>operator</replaceable>.
10228    The result of <token>ALL</token> is <quote>true</> if the comparison
10229    returns true for all subquery rows (including the special
10230    case where the subquery returns no rows).
10231    The result is <quote>false</> if the comparison returns false for any
10232    subquery row.
10233    The result is NULL if the comparison does not return false for any
10234    subquery row, and it returns NULL for at least one row.
10235   </para>
10236
10237   <para>
10238    See <xref linkend="row-wise-comparison"> for details about the meaning
10239    of a row-wise comparison.
10240   </para>
10241   </sect2>
10242
10243   <sect2>
10244    <title>Row-wise Comparison</title>
10245
10246    <indexterm zone="functions-subquery">
10247     <primary>comparison</primary>
10248     <secondary>subquery result row</secondary>
10249    </indexterm>
10250
10251 <synopsis>
10252 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
10253 </synopsis>
10254
10255   <para>
10256    The left-hand side is a row constructor,
10257    as described in <xref linkend="sql-syntax-row-constructors">.
10258    The right-hand side is a parenthesized subquery, which must return exactly
10259    as many columns as there are expressions in the left-hand row. Furthermore,
10260    the subquery cannot return more than one row.  (If it returns zero rows,
10261    the result is taken to be null.)  The left-hand side is evaluated and
10262    compared row-wise to the single subquery result row.
10263   </para>
10264
10265   <para>
10266    See <xref linkend="row-wise-comparison"> for details about the meaning
10267    of a row-wise comparison.
10268   </para>
10269   </sect2>
10270  </sect1>
10271
10272
10273  <sect1 id="functions-comparisons">
10274   <title>Row and Array Comparisons</title>
10275
10276   <indexterm>
10277    <primary>IN</primary>
10278   </indexterm>
10279
10280   <indexterm>
10281    <primary>NOT IN</primary>
10282   </indexterm>
10283
10284   <indexterm>
10285    <primary>ANY</primary>
10286   </indexterm>
10287
10288   <indexterm>
10289    <primary>ALL</primary>
10290   </indexterm>
10291
10292   <indexterm>
10293    <primary>SOME</primary>
10294   </indexterm>
10295
10296   <indexterm>
10297    <primary>row-wise comparison</primary>
10298   </indexterm>
10299
10300   <indexterm>
10301    <primary>comparison</primary>
10302    <secondary>row-wise</secondary>
10303   </indexterm>
10304
10305   <indexterm>
10306    <primary>IS DISTINCT FROM</primary>
10307   </indexterm>
10308
10309   <indexterm>
10310    <primary>IS NOT DISTINCT FROM</primary>
10311   </indexterm>
10312
10313   <para>
10314    This section describes several specialized constructs for making
10315    multiple comparisons between groups of values.  These forms are
10316    syntactically related to the subquery forms of the previous section,
10317    but do not involve subqueries.
10318    The forms involving array subexpressions are
10319    <productname>PostgreSQL</productname> extensions; the rest are
10320    <acronym>SQL</acronym>-compliant.
10321    All of the expression forms documented in this section return
10322    Boolean (true/false) results.
10323   </para>
10324
10325   <sect2>
10326    <title><literal>IN</literal></title>
10327
10328 <synopsis>
10329 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10330 </synopsis>
10331
10332   <para>
10333    The right-hand side is a parenthesized list
10334    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
10335    result is equal to any of the right-hand expressions.  This is a shorthand
10336    notation for
10337
10338 <synopsis>
10339 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
10340 OR
10341 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
10342 OR
10343 ...
10344 </synopsis>
10345   </para>
10346
10347   <para>
10348    Note that if the left-hand expression yields null, or if there are
10349    no equal right-hand values and at least one right-hand expression yields
10350    null, the result of the <token>IN</token> construct will be null, not false.
10351    This is in accordance with SQL's normal rules for Boolean combinations
10352    of null values.
10353   </para>
10354   </sect2>
10355
10356   <sect2>
10357    <title><literal>NOT IN</literal></title>
10358
10359 <synopsis>
10360 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10361 </synopsis>
10362
10363   <para>
10364    The right-hand side is a parenthesized list
10365    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
10366    result is unequal to all of the right-hand expressions.  This is a shorthand
10367    notation for
10368
10369 <synopsis>
10370 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
10371 AND
10372 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
10373 AND
10374 ...
10375 </synopsis>
10376   </para>
10377
10378   <para>
10379    Note that if the left-hand expression yields null, or if there are
10380    no equal right-hand values and at least one right-hand expression yields
10381    null, the result of the <token>NOT IN</token> construct will be null, not true
10382    as one might naively expect.
10383    This is in accordance with SQL's normal rules for Boolean combinations
10384    of null values.
10385   </para>
10386
10387   <tip>
10388   <para>
10389    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
10390    cases.  However, null values are much more likely to trip up the novice when
10391    working with <token>NOT IN</token> than when working with <token>IN</token>.
10392    It's best to express your condition positively if possible.
10393   </para>
10394   </tip>
10395   </sect2>
10396
10397   <sect2>
10398    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
10399
10400 <synopsis>
10401 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
10402 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
10403 </synopsis>
10404
10405   <para>
10406    The right-hand side is a parenthesized expression, which must yield an
10407    array value.
10408    The left-hand expression
10409    is evaluated and compared to each element of the array using the
10410    given <replaceable>operator</replaceable>, which must yield a Boolean
10411    result.
10412    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10413    The result is <quote>false</> if no true result is found (including the special
10414    case where the array has zero elements).
10415   </para>
10416
10417   <para>
10418    If the array expression yields a null array, the result of
10419    <token>ANY</token> will be null.  If the left-hand expression yields null,
10420    the result of <token>ANY</token> is ordinarily null (though a non-strict
10421    comparison operator could possibly yield a different result).
10422    Also, if the right-hand array contains any null elements and no true
10423    comparison result is obtained, the result of <token>ANY</token>
10424    will be null, not false (again, assuming a strict comparison operator).
10425    This is in accordance with SQL's normal rules for Boolean combinations
10426    of null values.
10427   </para>
10428
10429   <para>
10430    <token>SOME</token> is a synonym for <token>ANY</token>.
10431   </para>
10432   </sect2>
10433
10434   <sect2>
10435    <title><literal>ALL</literal> (array)</title>
10436
10437 <synopsis>
10438 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
10439 </synopsis>
10440
10441   <para>
10442    The right-hand side is a parenthesized expression, which must yield an
10443    array value.
10444    The left-hand expression
10445    is evaluated and compared to each element of the array using the
10446    given <replaceable>operator</replaceable>, which must yield a Boolean
10447    result.
10448    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
10449    (including the special case where the array has zero elements).
10450    The result is <quote>false</> if any false result is found.
10451   </para>
10452
10453   <para>
10454    If the array expression yields a null array, the result of
10455    <token>ALL</token> will be null.  If the left-hand expression yields null,
10456    the result of <token>ALL</token> is ordinarily null (though a non-strict
10457    comparison operator could possibly yield a different result).
10458    Also, if the right-hand array contains any null elements and no false
10459    comparison result is obtained, the result of <token>ALL</token>
10460    will be null, not true (again, assuming a strict comparison operator).
10461    This is in accordance with SQL's normal rules for Boolean combinations
10462    of null values.
10463   </para>
10464   </sect2>
10465
10466   <sect2 id="row-wise-comparison">
10467    <title>Row-wise Comparison</title>
10468
10469 <synopsis>
10470 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
10471 </synopsis>
10472
10473   <para>
10474    Each side is a row constructor,
10475    as described in <xref linkend="sql-syntax-row-constructors">.
10476    The two row values must have the same number of fields.
10477    Each side is evaluated and they are compared row-wise.  Row comparisons
10478    are allowed when the <replaceable>operator</replaceable> is
10479    <literal>=</>,
10480    <literal>&lt;&gt;</>,
10481    <literal>&lt;</>,
10482    <literal>&lt;=</>,
10483    <literal>&gt;</> or
10484    <literal>&gt;=</>,
10485    or has semantics similar to one of these.  (To be specific, an operator
10486    can be a row comparison operator if it is a member of a B-Tree operator
10487    class, or is the negator of the <literal>=</> member of a B-Tree operator
10488    class.)
10489   </para>
10490
10491   <para>
10492    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
10493    from the others.  Two rows are considered
10494    equal if all their corresponding members are non-null and equal; the rows
10495    are unequal if any corresponding members are non-null and unequal;
10496    otherwise the result of the row comparison is unknown (null).
10497   </para>
10498
10499   <para>
10500    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
10501    <literal>&gt;=</> cases, the row elements are compared left-to-right,
10502    stopping as soon as an unequal or null pair of elements is found.
10503    If either of this pair of elements is null, the result of the
10504    row comparison is unknown (null); otherwise comparison of this pair
10505    of elements determines the result.  For example,
10506    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
10507    yields true, not null, because the third pair of elements are not
10508    considered.
10509   </para>
10510
10511   <note>
10512    <para>
10513     Prior to <productname>PostgreSQL</productname> 8.2, the
10514     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
10515     cases were not handled per SQL specification.  A comparison like
10516     <literal>ROW(a,b) &lt; ROW(c,d)</>
10517     was implemented as
10518     <literal>a &lt; c AND b &lt; d</>
10519     whereas the correct behavior is equivalent to
10520     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
10521    </para>
10522   </note>
10523
10524 <synopsis>
10525 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
10526 </synopsis>
10527
10528   <para>
10529    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
10530    but it does not yield null for null inputs.  Instead, any null value is
10531    considered unequal to (distinct from) any non-null value, and any two
10532    nulls are considered equal (not distinct).  Thus the result will always
10533    be either true or false, never null.
10534   </para>
10535
10536 <synopsis>
10537 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
10538 </synopsis>
10539
10540   <para>
10541    This construct is similar to a <literal>=</literal> row comparison,
10542    but it does not yield null for null inputs.  Instead, any null value is
10543    considered unequal to (distinct from) any non-null value, and any two
10544    nulls are considered equal (not distinct).  Thus the result will always
10545    be either true or false, never null.
10546   </para>
10547
10548   </sect2>
10549  </sect1>
10550
10551  <sect1 id="functions-srf">
10552   <title>Set Returning Functions</title>
10553
10554   <indexterm zone="functions-srf">
10555    <primary>set returning functions</primary>
10556    <secondary>functions</secondary>
10557   </indexterm>
10558
10559   <indexterm>
10560    <primary>generate_series</primary>
10561   </indexterm>
10562
10563   <para>
10564    This section describes functions that possibly return more than one row.
10565    Currently the only functions in this class are series generating functions,
10566    as detailed in <xref linkend="functions-srf-series">.
10567   </para>
10568
10569   <table id="functions-srf-series">
10570    <title>Series Generating Functions</title>
10571    <tgroup cols="4">
10572     <thead>
10573      <row>
10574       <entry>Function</entry>
10575       <entry>Argument Type</entry>
10576       <entry>Return Type</entry>
10577       <entry>Description</entry>
10578      </row>
10579     </thead>
10580
10581     <tbody>
10582      <row>
10583       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>)</literal></entry>
10584       <entry><type>int</type> or <type>bigint</type></entry>
10585       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
10586       <entry>
10587        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
10588        with a step size of one
10589       </entry>
10590      </row>
10591
10592      <row>
10593       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</literal></entry>
10594       <entry><type>int</type> or <type>bigint</type></entry>
10595       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
10596       <entry>
10597        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
10598        with a step size of <parameter>step</parameter>
10599       </entry>
10600      </row>
10601
10602     </tbody>
10603    </tgroup>
10604   </table>
10605
10606   <para>
10607    When <parameter>step</parameter> is positive, zero rows are returned if
10608    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
10609    Conversely, when <parameter>step</parameter> is negative, zero rows are
10610    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
10611    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
10612    for <parameter>step</parameter> to be zero. Some examples follow:
10613 <programlisting>
10614 select * from generate_series(2,4);
10615  generate_series
10616 -----------------
10617                2
10618                3
10619                4
10620 (3 rows)
10621
10622 select * from generate_series(5,1,-2);
10623  generate_series
10624 -----------------
10625                5
10626                3
10627                1
10628 (3 rows)
10629
10630 select * from generate_series(4,3);
10631  generate_series
10632 -----------------
10633 (0 rows)
10634
10635 select current_date + s.a as dates from generate_series(0,14,7) as s(a);
10636    dates
10637 ------------
10638  2004-02-05
10639  2004-02-12
10640  2004-02-19
10641 (3 rows)
10642 </programlisting>
10643   </para>
10644  </sect1>
10645
10646  <sect1 id="functions-info">
10647   <title>System Information Functions</title>
10648
10649   <para>
10650    <xref linkend="functions-info-session-table"> shows several
10651    functions that extract session and system information.
10652   </para>
10653
10654   <para>
10655    In addition to the functions listed in this section, there are a number of
10656    functions related to the statistics system that also provide system
10657    information. See <xref linkend="monitoring-stats-views"> for more
10658    information.
10659   </para>
10660
10661    <table id="functions-info-session-table">
10662     <title>Session Information Functions</title>
10663     <tgroup cols="3">
10664      <thead>
10665       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
10666      </thead>
10667
10668      <tbody>
10669       <row>
10670        <entry><literal><function>current_database</function>()</literal></entry>
10671        <entry><type>name</type></entry>
10672        <entry>name of current database</entry>
10673       </row>
10674
10675       <row>
10676        <entry><literal><function>current_schema</function>()</literal></entry>
10677        <entry><type>name</type></entry>
10678        <entry>name of current schema</entry>
10679       </row>
10680
10681       <row>
10682        <entry><literal><function>current_schemas</function>(<type>boolean</type>)</literal></entry>
10683        <entry><type>name[]</type></entry>
10684        <entry>names of schemas in search path optionally including implicit schemas</entry>
10685       </row>
10686
10687       <row>
10688        <entry><literal><function>current_user</function></literal></entry>
10689        <entry><type>name</type></entry>
10690        <entry>user name of current execution context</entry>
10691       </row>
10692
10693       <row>
10694        <entry><literal><function>inet_client_addr</function>()</literal></entry>
10695        <entry><type>inet</type></entry>
10696        <entry>address of the remote connection</entry>
10697       </row>
10698
10699       <row>
10700        <entry><literal><function>inet_client_port</function>()</literal></entry>
10701        <entry><type>int</type></entry>
10702        <entry>port of the remote connection</entry>
10703       </row>
10704
10705       <row>
10706        <entry><literal><function>inet_server_addr</function>()</literal></entry>
10707        <entry><type>inet</type></entry>
10708        <entry>address of the local connection</entry>
10709       </row>
10710
10711       <row>
10712        <entry><literal><function>inet_server_port</function>()</literal></entry>
10713        <entry><type>int</type></entry>
10714        <entry>port of the local connection</entry>
10715       </row>
10716
10717       <row>
10718        <entry><literal><function>pg_my_temp_schema</function>()</literal></entry>
10719        <entry><type>oid</type></entry>
10720        <entry>OID of session's temporary schema, or 0 if none</entry>
10721       </row>
10722
10723       <row>
10724        <entry><literal><function>pg_is_other_temp_schema</function>(<type>oid</type>)</literal></entry>
10725        <entry><type>boolean</type></entry>
10726        <entry>is schema another session's temporary schema?</entry>
10727       </row>
10728
10729       <row>
10730        <entry><literal><function>pg_postmaster_start_time</function>()</literal></entry>
10731        <entry><type>timestamp with time zone</type></entry>
10732        <entry>server start time</entry>
10733       </row>
10734
10735       <row>
10736        <entry><literal><function>session_user</function></literal></entry>
10737        <entry><type>name</type></entry>
10738        <entry>session user name</entry>
10739       </row>
10740
10741       <row>
10742        <entry><literal><function>user</function></literal></entry>
10743        <entry><type>name</type></entry>
10744        <entry>equivalent to <function>current_user</function></entry>
10745       </row>
10746
10747       <row>
10748        <entry><literal><function>version</function>()</literal></entry>
10749        <entry><type>text</type></entry>
10750        <entry><productname>PostgreSQL</> version information</entry>
10751       </row>
10752      </tbody>
10753     </tgroup>
10754    </table>
10755
10756    <indexterm>
10757     <primary>user</primary>
10758     <secondary>current</secondary>
10759    </indexterm>
10760
10761    <indexterm>
10762     <primary>schema</primary>
10763     <secondary>current</secondary>
10764    </indexterm>
10765
10766    <indexterm>
10767     <primary>search path</primary>
10768     <secondary>current</secondary>
10769    </indexterm>
10770
10771    <indexterm>
10772     <primary>current_database</primary>
10773    </indexterm>
10774
10775    <indexterm>
10776     <primary>current_schema</primary>
10777    </indexterm>
10778
10779    <indexterm>
10780     <primary>current_user</primary>
10781    </indexterm>
10782
10783    <para>
10784     The <function>session_user</function> is normally the user who initiated
10785     the current database connection; but superusers can change this setting
10786     with <xref linkend="sql-set-session-authorization" endterm="sql-set-session-authorization-title">.
10787     The <function>current_user</function> is the user identifier
10788     that is applicable for permission checking. Normally, it is equal
10789     to the session user, but it can be changed with
10790     <xref linkend="sql-set-role" endterm="sql-set-role-title">.
10791     It also changes during the execution of
10792     functions with the attribute <literal>SECURITY DEFINER</literal>.
10793     In Unix parlance, the session user is the <quote>real user</quote> and
10794     the current user is the <quote>effective user</quote>.
10795    </para>
10796
10797    <note>
10798     <para>
10799      <function>current_user</function>, <function>session_user</function>, and
10800      <function>user</function> have special syntactic status in <acronym>SQL</acronym>:
10801      they must be called without trailing parentheses.
10802     </para>
10803    </note>
10804
10805    <para>
10806     <function>current_schema</function> returns the name of the schema that is
10807     at the front of the search path (or a null value if the search path is
10808     empty).  This is the schema that will be used for any tables or
10809     other named objects that are created without specifying a target schema.
10810     <function>current_schemas(boolean)</function> returns an array of the names of all
10811     schemas presently in the search path.  The Boolean option determines whether or not
10812     implicitly included system schemas such as <literal>pg_catalog</> are included in the search 
10813     path returned.
10814    </para>
10815
10816    <note>
10817     <para>
10818      The search path can be altered at run time.  The command is:
10819 <programlisting>
10820 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
10821 </programlisting>
10822     </para>
10823    </note>
10824
10825    <indexterm>
10826     <primary>inet_client_addr</primary>
10827    </indexterm>
10828
10829    <indexterm>
10830     <primary>inet_client_port</primary>
10831    </indexterm>
10832
10833    <indexterm>
10834     <primary>inet_server_addr</primary>
10835    </indexterm>
10836
10837    <indexterm>
10838     <primary>inet_server_port</primary>
10839    </indexterm>
10840
10841    <para>
10842      <function>inet_client_addr</function> returns the IP address of the
10843      current client, and <function>inet_client_port</function> returns the
10844      port number.
10845      <function>inet_server_addr</function> returns the IP address on which
10846      the server accepted the current connection, and
10847      <function>inet_server_port</function> returns the port number.
10848      All these functions return NULL if the current connection is via a
10849      Unix-domain socket.
10850    </para>
10851
10852    <indexterm>
10853     <primary>pg_my_temp_schema</primary>
10854    </indexterm>
10855
10856    <indexterm>
10857     <primary>pg_is_other_temp_schema</primary>
10858    </indexterm>
10859
10860    <para>
10861     <function>pg_my_temp_schema</function> returns the OID of the current
10862     session's temporary schema, or 0 if it has none (because it has not
10863     created any temporary tables).
10864     <function>pg_is_other_temp_schema</function> returns true if the
10865     given OID is the OID of any other session's temporary schema.
10866     (This can be useful, for example, to exclude other sessions' temporary
10867     tables from a catalog display.)
10868    </para>
10869
10870    <indexterm>
10871     <primary>pg_postmaster_start_time</primary>
10872    </indexterm>
10873
10874    <para>
10875      <function>pg_postmaster_start_time</function> returns the
10876      <type>timestamp with time zone</type> when the
10877      server started.
10878    </para>
10879
10880    <indexterm>
10881     <primary>version</primary>
10882    </indexterm>
10883
10884    <para>
10885     <function>version</function> returns a string describing the
10886     <productname>PostgreSQL</productname> server's version.
10887    </para>
10888
10889   <indexterm>
10890    <primary>privilege</primary>
10891    <secondary>querying</secondary>
10892   </indexterm>
10893
10894   <para>
10895    <xref linkend="functions-info-access-table"> lists functions that
10896    allow the user to query object access privileges programmatically.
10897    See <xref linkend="ddl-priv"> for more information about
10898    privileges.
10899   </para>
10900
10901    <table id="functions-info-access-table">
10902     <title>Access Privilege Inquiry Functions</title>
10903     <tgroup cols="3">
10904      <thead>
10905       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
10906      </thead>
10907
10908      <tbody>
10909       <row>
10910        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
10911                                   <parameter>database</parameter>,
10912                                   <parameter>privilege</parameter>)</literal>
10913        </entry>
10914        <entry><type>boolean</type></entry>
10915        <entry>does user have privilege for database</entry>
10916       </row>
10917       <row>
10918        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
10919                                   <parameter>privilege</parameter>)</literal>
10920        </entry>
10921        <entry><type>boolean</type></entry>
10922        <entry>does current user have privilege for database</entry>
10923       </row>
10924       <row>
10925        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
10926                                   <parameter>function</parameter>,
10927                                   <parameter>privilege</parameter>)</literal>
10928        </entry>
10929        <entry><type>boolean</type></entry>
10930        <entry>does user have privilege for function</entry>
10931       </row>
10932       <row>
10933        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
10934                                   <parameter>privilege</parameter>)</literal>
10935        </entry>
10936        <entry><type>boolean</type></entry>
10937        <entry>does current user have privilege for function</entry>
10938       </row>
10939       <row>
10940        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
10941                                   <parameter>language</parameter>,
10942                                   <parameter>privilege</parameter>)</literal>
10943        </entry>
10944        <entry><type>boolean</type></entry>
10945        <entry>does user have privilege for language</entry>
10946       </row>
10947       <row>
10948        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
10949                                   <parameter>privilege</parameter>)</literal>
10950        </entry>
10951        <entry><type>boolean</type></entry>
10952        <entry>does current user have privilege for language</entry>
10953       </row>
10954       <row>
10955        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
10956                                   <parameter>schema</parameter>,
10957                                   <parameter>privilege</parameter>)</literal>
10958        </entry>
10959        <entry><type>boolean</type></entry>
10960        <entry>does user have privilege for schema</entry>
10961       </row>
10962       <row>
10963        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
10964                                   <parameter>privilege</parameter>)</literal>
10965        </entry>
10966        <entry><type>boolean</type></entry>
10967        <entry>does current user have privilege for schema</entry>
10968       </row>
10969       <row>
10970        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
10971                                   <parameter>table</parameter>,
10972                                   <parameter>privilege</parameter>)</literal>
10973        </entry>
10974        <entry><type>boolean</type></entry>
10975        <entry>does user have privilege for table</entry>
10976       </row>
10977       <row>
10978        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
10979                                   <parameter>privilege</parameter>)</literal>
10980        </entry>
10981        <entry><type>boolean</type></entry>
10982        <entry>does current user have privilege for table</entry>
10983       </row>
10984       <row>
10985        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
10986                                   <parameter>tablespace</parameter>,
10987                                   <parameter>privilege</parameter>)</literal>
10988        </entry>
10989        <entry><type>boolean</type></entry>
10990        <entry>does user have privilege for tablespace</entry>
10991       </row>
10992       <row>
10993        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
10994                                   <parameter>privilege</parameter>)</literal>
10995        </entry>
10996        <entry><type>boolean</type></entry>
10997        <entry>does current user have privilege for tablespace</entry>
10998       </row>
10999       <row>
11000        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
11001                                   <parameter>role</parameter>,
11002                                   <parameter>privilege</parameter>)</literal>
11003        </entry>
11004        <entry><type>boolean</type></entry>
11005        <entry>does user have privilege for role</entry>
11006       </row>
11007       <row>
11008        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
11009                                   <parameter>privilege</parameter>)</literal>
11010        </entry>
11011        <entry><type>boolean</type></entry>
11012        <entry>does current user have privilege for role</entry>
11013       </row>
11014      </tbody>
11015     </tgroup>
11016    </table>
11017
11018    <indexterm>
11019     <primary>has_database_privilege</primary>
11020    </indexterm>
11021    <indexterm>
11022     <primary>has_function_privilege</primary>
11023    </indexterm>
11024    <indexterm>
11025     <primary>has_language_privilege</primary>
11026    </indexterm>
11027    <indexterm>
11028     <primary>has_schema_privilege</primary>
11029    </indexterm>
11030    <indexterm>
11031     <primary>has_table_privilege</primary>
11032    </indexterm>
11033    <indexterm>
11034     <primary>has_tablespace_privilege</primary>
11035    </indexterm>
11036    <indexterm>
11037     <primary>pg_has_role</primary>
11038    </indexterm>
11039
11040    <para>
11041     <function>has_database_privilege</function> checks whether a user
11042     can access a database in a particular way.  The possibilities for its
11043     arguments are analogous to <function>has_table_privilege</function>.
11044     The desired access privilege type must evaluate to
11045     <literal>CREATE</literal>,
11046     <literal>CONNECT</literal>,
11047     <literal>TEMPORARY</literal>, or
11048     <literal>TEMP</literal> (which is equivalent to
11049     <literal>TEMPORARY</literal>).
11050    </para>
11051
11052    <para>
11053     <function>has_function_privilege</function> checks whether a user
11054     can access a function in a particular way.  The possibilities for its
11055     arguments are analogous to <function>has_table_privilege</function>.
11056     When specifying a function by a text string rather than by OID,
11057     the allowed input is the same as for the <type>regprocedure</> data type
11058     (see <xref linkend="datatype-oid">).
11059     The desired access privilege type must evaluate to
11060     <literal>EXECUTE</literal>.
11061     An example is:
11062 <programlisting>
11063 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
11064 </programlisting>
11065    </para>
11066
11067    <para>
11068     <function>has_language_privilege</function> checks whether a user
11069     can access a procedural language in a particular way.  The possibilities
11070     for its arguments are analogous to <function>has_table_privilege</function>.
11071     The desired access privilege type must evaluate to
11072     <literal>USAGE</literal>.
11073    </para>
11074
11075    <para>
11076     <function>has_schema_privilege</function> checks whether a user
11077     can access a schema in a particular way.  The possibilities for its
11078     arguments are analogous to <function>has_table_privilege</function>.
11079     The desired access privilege type must evaluate to
11080     <literal>CREATE</literal> or
11081     <literal>USAGE</literal>.
11082    </para>
11083
11084    <para>
11085     <function>has_table_privilege</function> checks whether a user
11086     can access a table in a particular way.  The user can be
11087     specified by name or by OID
11088     (<literal>pg_authid.oid</literal>), or if the argument is
11089     omitted
11090     <function>current_user</function> is assumed.  The table can be specified
11091     by name or by OID.  (Thus, there are actually six variants of
11092     <function>has_table_privilege</function>, which can be distinguished by
11093     the number and types of their arguments.)  When specifying by name,
11094     the name can be schema-qualified if necessary.
11095     The desired access privilege type
11096     is specified by a text string, which must evaluate to one of the
11097     values <literal>SELECT</literal>, <literal>INSERT</literal>,
11098     <literal>UPDATE</literal>, <literal>DELETE</literal>,
11099     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.
11100     (Case of the string is not significant, however.)
11101     An example is:
11102 <programlisting>
11103 SELECT has_table_privilege('myschema.mytable', 'select');
11104 </programlisting>
11105    </para>
11106
11107    <para>
11108     <function>has_tablespace_privilege</function> checks whether a user
11109     can access a tablespace in a particular way.  The possibilities for its
11110     arguments are analogous to <function>has_table_privilege</function>.
11111     The desired access privilege type must evaluate to
11112     <literal>CREATE</literal>.
11113    </para>
11114
11115    <para>
11116     <function>pg_has_role</function> checks whether a user
11117     can access a role in a particular way.  The possibilities for its
11118     arguments are analogous to <function>has_table_privilege</function>.
11119     The desired access privilege type must evaluate to
11120     <literal>MEMBER</literal> or
11121     <literal>USAGE</literal>.
11122     <literal>MEMBER</literal> denotes direct or indirect membership in
11123     the role (that is, the right to do <command>SET ROLE</>), while
11124     <literal>USAGE</literal> denotes whether the privileges of the role
11125     are immediately available without doing <command>SET ROLE</>.
11126    </para>
11127
11128   <para>
11129    To test whether a user holds a grant option on the privilege,
11130    append <literal>WITH GRANT OPTION</literal> to the privilege key
11131    word; for example <literal>'UPDATE WITH GRANT OPTION'</literal>.
11132   </para>
11133
11134   <para>
11135    <xref linkend="functions-info-schema-table"> shows functions that
11136    determine whether a certain object is <firstterm>visible</> in the
11137    current schema search path.
11138    For example, a table is said to be visible if its
11139    containing schema is in the search path and no table of the same
11140    name appears earlier in the search path.  This is equivalent to the
11141    statement that the table can be referenced by name without explicit
11142    schema qualification.  To list the names of all visible tables:
11143 <programlisting>
11144 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
11145 </programlisting>
11146   </para>
11147
11148    <table id="functions-info-schema-table">
11149     <title>Schema Visibility Inquiry Functions</title>
11150     <tgroup cols="3">
11151      <thead>
11152       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11153      </thead>
11154
11155      <tbody>
11156       <row>
11157        <entry><literal><function>pg_conversion_is_visible</function>(<parameter>conversion_oid</parameter>)</literal>
11158        </entry>
11159        <entry><type>boolean</type></entry>
11160        <entry>is conversion visible in search path</entry>
11161       </row>
11162       <row>
11163        <entry><literal><function>pg_function_is_visible</function>(<parameter>function_oid</parameter>)</literal>
11164        </entry>
11165        <entry><type>boolean</type></entry>
11166        <entry>is function visible in search path</entry>
11167       </row>
11168       <row>
11169        <entry><literal><function>pg_operator_is_visible</function>(<parameter>operator_oid</parameter>)</literal>
11170        </entry>
11171        <entry><type>boolean</type></entry>
11172        <entry>is operator visible in search path</entry>
11173       </row>
11174       <row>
11175        <entry><literal><function>pg_opclass_is_visible</function>(<parameter>opclass_oid</parameter>)</literal>
11176        </entry>
11177        <entry><type>boolean</type></entry>
11178        <entry>is operator class visible in search path</entry>
11179       </row>
11180       <row>
11181        <entry><literal><function>pg_table_is_visible</function>(<parameter>table_oid</parameter>)</literal>
11182        </entry>
11183        <entry><type>boolean</type></entry>
11184        <entry>is table visible in search path</entry>
11185       </row>
11186       <row>
11187        <entry><literal><function>pg_ts_config_is_visible</function>(<parameter>config_oid</parameter>)</literal>
11188        </entry>
11189        <entry><type>boolean</type></entry>
11190        <entry>is text search configuration visible in search path</entry>
11191       </row>
11192       <row>
11193        <entry><literal><function>pg_ts_dict_is_visible</function>(<parameter>dict_oid</parameter>)</literal>
11194        </entry>
11195        <entry><type>boolean</type></entry>
11196        <entry>is text search dictionary visible in search path</entry>
11197       </row>
11198       <row>
11199        <entry><literal><function>pg_ts_parser_is_visible</function>(<parameter>parser_oid</parameter>)</literal>
11200        </entry>
11201        <entry><type>boolean</type></entry>
11202        <entry>is text search parser visible in search path</entry>
11203       </row>
11204       <row>
11205        <entry><literal><function>pg_ts_template_is_visible</function>(<parameter>template_oid</parameter>)</literal>
11206        </entry>
11207        <entry><type>boolean</type></entry>
11208        <entry>is text search template visible in search path</entry>
11209       </row>
11210       <row>
11211        <entry><literal><function>pg_type_is_visible</function>(<parameter>type_oid</parameter>)</literal>
11212        </entry>
11213        <entry><type>boolean</type></entry>
11214        <entry>is type (or domain) visible in search path</entry>
11215       </row>
11216      </tbody>
11217     </tgroup>
11218    </table>
11219
11220    <indexterm>
11221     <primary>pg_conversion_is_visible</primary>
11222    </indexterm>
11223    <indexterm>
11224     <primary>pg_function_is_visible</primary>
11225    </indexterm>
11226    <indexterm>
11227     <primary>pg_operator_is_visible</primary>
11228    </indexterm>
11229    <indexterm>
11230     <primary>pg_opclass_is_visible</primary>
11231    </indexterm>
11232    <indexterm>
11233     <primary>pg_table_is_visible</primary>
11234    </indexterm>
11235    <indexterm>
11236     <primary>pg_ts_config_is_visible</primary>
11237    </indexterm>
11238    <indexterm>
11239     <primary>pg_ts_dict_is_visible</primary>
11240    </indexterm>
11241    <indexterm>
11242     <primary>pg_ts_parser_is_visible</primary>
11243    </indexterm>
11244    <indexterm>
11245     <primary>pg_ts_template_is_visible</primary>
11246    </indexterm>
11247    <indexterm>
11248     <primary>pg_type_is_visible</primary>
11249    </indexterm>
11250
11251    <para>
11252     Each function performs the visibility check for one type of database
11253     object.  Note that <function>pg_table_is_visible</function> can also be used
11254     with views, indexes and sequences; <function>pg_type_is_visible</function>
11255     can also be used with domains. For functions and operators, an object in
11256     the search path is visible if there is no object of the same name
11257     <emphasis>and argument data type(s)</> earlier in the path.  For operator
11258     classes, both name and associated index access method are considered.
11259    </para>
11260
11261    <para>
11262     All these functions require object OIDs to identify the object to be
11263     checked.  If you want to test an object by name, it is convenient to use
11264     the OID alias types (<type>regclass</>, <type>regtype</>,
11265     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
11266     or <type>regdictionary</>),
11267     for example:
11268 <programlisting>
11269 SELECT pg_type_is_visible('myschema.widget'::regtype);
11270 </programlisting>
11271     Note that it would not make much sense to test an unqualified name in
11272     this way &mdash; if the name can be recognized at all, it must be visible.
11273    </para>
11274
11275    <indexterm>
11276     <primary>format_type</primary>
11277    </indexterm>
11278
11279    <indexterm>
11280     <primary>pg_get_viewdef</primary>
11281    </indexterm>
11282
11283    <indexterm>
11284     <primary>pg_get_ruledef</primary>
11285    </indexterm>
11286
11287    <indexterm>
11288     <primary>pg_get_indexdef</primary>
11289    </indexterm>
11290
11291    <indexterm>
11292     <primary>pg_get_triggerdef</primary>
11293    </indexterm>
11294
11295    <indexterm>
11296     <primary>pg_get_constraintdef</primary>
11297    </indexterm>
11298
11299    <indexterm>
11300     <primary>pg_get_expr</primary>
11301    </indexterm>
11302
11303    <indexterm>
11304     <primary>pg_get_userbyid</primary>
11305    </indexterm>
11306
11307    <indexterm>
11308     <primary>pg_get_serial_sequence</primary>
11309    </indexterm>
11310
11311    <indexterm>
11312     <primary>pg_tablespace_databases</primary>
11313    </indexterm>
11314
11315   <para>
11316    <xref linkend="functions-info-catalog-table"> lists functions that
11317    extract information from the system catalogs.
11318   </para>
11319
11320    <table id="functions-info-catalog-table">
11321     <title>System Catalog Information Functions</title>
11322     <tgroup cols="3">
11323      <thead>
11324       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11325      </thead>
11326
11327      <tbody>
11328       <row>
11329        <entry><literal><function>format_type</function>(<parameter>type_oid</parameter>, <parameter>typemod</>)</literal></entry>
11330        <entry><type>text</type></entry>
11331        <entry>get SQL name of a data type</entry>
11332       </row>
11333       <row>
11334        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>)</literal></entry>
11335        <entry><type>text</type></entry>
11336        <entry>get definition of a constraint</entry>
11337       </row>
11338       <row>
11339        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11340        <entry><type>text</type></entry>
11341        <entry>get definition of a constraint</entry>
11342       </row>
11343       <row>
11344        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>)</literal></entry>
11345        <entry><type>text</type></entry>
11346        <entry>decompile internal form of an expression, assuming that any Vars
11347        in it refer to the relation indicated by the second parameter</entry>
11348       </row>
11349       <row>
11350        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</literal></entry>
11351        <entry><type>text</type></entry>
11352        <entry>decompile internal form of an expression, assuming that any Vars
11353        in it refer to the relation indicated by the second parameter</entry>
11354       </row>
11355       <row>
11356        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
11357        <entry><type>text</type></entry>
11358        <entry>get <command>CREATE INDEX</> command for index</entry>
11359       </row>
11360       <row>
11361        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</literal></entry>
11362        <entry><type>text</type></entry>
11363        <entry>get <command>CREATE INDEX</> command for index,
11364        or definition of just one index column when
11365        <parameter>column_no</> is not zero</entry>
11366       </row>
11367       <row>
11368        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>)</literal></entry>
11369        <entry><type>text</type></entry>
11370        <entry>get <command>CREATE RULE</> command for rule</entry>
11371       </row>
11372       <row>
11373        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11374        <entry><type>text</type></entry>
11375        <entry>get <command>CREATE RULE</> command for rule</entry>
11376       </row>
11377       <row>
11378        <entry><literal><function>pg_get_serial_sequence</function>(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</literal></entry>
11379        <entry><type>text</type></entry>
11380        <entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
11381        uses</entry>
11382       </row>
11383       <row>
11384        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
11385        <entry><type>text</type></entry>
11386        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
11387       </row>
11388       <row>
11389        <entry><literal><function>pg_get_userbyid</function>(<parameter>roleid</parameter>)</literal></entry>
11390        <entry><type>name</type></entry>
11391        <entry>get role name with given ID</entry>
11392       </row>
11393       <row>
11394        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>)</literal></entry>
11395        <entry><type>text</type></entry>
11396        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
11397       </row>
11398       <row>
11399        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</literal></entry>
11400        <entry><type>text</type></entry>
11401        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
11402       </row>
11403       <row>
11404        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>)</literal></entry>
11405        <entry><type>text</type></entry>
11406        <entry>get underlying <command>SELECT</command> command for view</entry>
11407       </row>
11408       <row>
11409        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11410        <entry><type>text</type></entry>
11411        <entry>get underlying <command>SELECT</command> command for view</entry>
11412       </row>
11413       <row>
11414        <entry><literal><function>pg_tablespace_databases</function>(<parameter>tablespace_oid</parameter>)</literal></entry>
11415        <entry><type>setof oid</type></entry>
11416        <entry>get the set of database OIDs that have objects in the tablespace</entry>
11417       </row>
11418      </tbody>
11419     </tgroup>
11420    </table>
11421
11422   <para>
11423    <function>format_type</function> returns the SQL name of a data type that
11424    is identified by its type OID and possibly a type modifier.  Pass NULL
11425    for the type modifier if no specific modifier is known.
11426   </para>
11427
11428   <para>
11429    <function>pg_get_constraintdef</function>,
11430    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
11431    and <function>pg_get_triggerdef</function>, respectively reconstruct the
11432    creating command for a constraint, index, rule, or trigger. (Note that this
11433    is a decompiled reconstruction, not the original text of the command.)
11434    <function>pg_get_expr</function> decompiles the internal form of an
11435    individual expression, such as the default value for a column.  It can be
11436    useful when examining the contents of system catalogs.
11437    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
11438    query that defines a view. Most of these functions come in two variants,
11439    one of which can optionally <quote>pretty-print</> the result.  The
11440    pretty-printed format is more readable, but the default format is more
11441    likely to be interpreted the same way by future versions of
11442    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
11443    purposes.  Passing <literal>false</> for the pretty-print parameter yields
11444    the same result as the variant that does not have the parameter at all.
11445   </para>
11446
11447   <para>
11448    <function>pg_get_serial_sequence</function> returns the name of the
11449    sequence associated with a column, or NULL if no sequence is associated
11450    with the column.  The first input parameter is a table name with
11451    optional schema, and the second parameter is a column name.  Because
11452    the first parameter is potentially a schema and table, it is not treated
11453    as a double-quoted identifier, meaning it is lowercased by default,
11454    while the second parameter, being just a column name, is treated as
11455    double-quoted and has its case preserved.  The function returns a value
11456    suitably formatted for passing to the sequence functions (see <xref
11457    linkend="functions-sequence">).  This association can be modified or
11458    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
11459    probably should have been called
11460    <function>pg_get_owned_sequence</function>; its name reflects the fact
11461    that it's typically used with <type>serial</> or <type>bigserial</>
11462    columns.)
11463   </para>
11464
11465   <para>
11466    <function>pg_get_userbyid</function> extracts a role's name given
11467    its OID.
11468   </para>
11469
11470   <para>
11471    <function>pg_tablespace_databases</function> allows a tablespace to be
11472    examined. It returns the set of OIDs of databases that have objects stored
11473    in the tablespace. If this function returns any rows, the tablespace is not
11474    empty and cannot be dropped. To display the specific objects populating the
11475    tablespace, you will need to connect to the databases identified by
11476    <function>pg_tablespace_databases</function> and query their
11477    <structname>pg_class</> catalogs.
11478   </para>
11479
11480    <indexterm>
11481     <primary>col_description</primary>
11482    </indexterm>
11483
11484    <indexterm>
11485     <primary>obj_description</primary>
11486    </indexterm>
11487
11488    <indexterm>
11489     <primary>shobj_description</primary>
11490    </indexterm>
11491
11492    <indexterm>
11493     <primary>comment</primary>
11494     <secondary sortas="database objects">about database objects</secondary>
11495    </indexterm>
11496
11497    <para>
11498     The functions shown in <xref linkend="functions-info-comment-table">
11499     extract comments previously stored with the <xref linkend="sql-comment"
11500     endterm="sql-comment-title"> command.  A null value is returned if no
11501     comment could be found matching the specified parameters.
11502    </para>
11503
11504    <table id="functions-info-comment-table">
11505     <title>Comment Information Functions</title>
11506     <tgroup cols="3">
11507      <thead>
11508       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11509      </thead>
11510
11511      <tbody>
11512       <row>
11513        <entry><literal><function>col_description</function>(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</literal></entry>
11514        <entry><type>text</type></entry>
11515        <entry>get comment for a table column</entry>
11516       </row>
11517       <row>
11518        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
11519        <entry><type>text</type></entry>
11520        <entry>get comment for a database object</entry>
11521       </row>
11522       <row>
11523        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>)</literal></entry>
11524        <entry><type>text</type></entry>
11525        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
11526       </row>
11527       <row>
11528        <entry><literal><function>shobj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
11529        <entry><type>text</type></entry>
11530        <entry>get comment for a shared database object</entry>
11531       </row>
11532      </tbody>
11533     </tgroup>
11534    </table>
11535
11536    <para>
11537     <function>col_description</function> returns the comment for a table column,
11538     which is specified by the OID of its table and its column number.
11539     <function>obj_description</function> cannot be used for table columns since
11540     columns do not have OIDs of their own.
11541    </para>
11542
11543    <para>
11544     The two-parameter form of <function>obj_description</function> returns the
11545     comment for a database object specified by its OID and the name of the
11546     containing system catalog.  For example,
11547     <literal>obj_description(123456,'pg_class')</literal>
11548     would retrieve the comment for a table with OID 123456.
11549     The one-parameter form of <function>obj_description</function> requires only
11550     the object OID.  It is now deprecated since there is no guarantee that
11551     OIDs are unique across different system catalogs; therefore, the wrong
11552     comment could be returned.
11553    </para>
11554
11555    <para>
11556     <function>shobj_description</function> is used just like
11557     <function>obj_description</function> only that it is used for retrieving
11558     comments on shared objects.  Some system catalogs are global to all
11559     databases within each cluster and their descriptions are stored globally
11560     as well.
11561    </para>
11562
11563    <indexterm>
11564     <primary>txid_current</primary>
11565    </indexterm>
11566
11567    <indexterm>
11568     <primary>txid_current_snapshot</primary>
11569    </indexterm>
11570
11571    <indexterm>
11572     <primary>txid_snapshot_xmin</primary>
11573    </indexterm>
11574
11575    <indexterm>
11576     <primary>txid_snapshot_xmax</primary>
11577    </indexterm>
11578
11579    <indexterm>
11580     <primary>txid_snapshot_xip</primary>
11581    </indexterm>
11582
11583    <indexterm>
11584     <primary>txid_visible_in_snapshot</primary>
11585    </indexterm>
11586
11587    <para>
11588     The functions shown in <xref linkend="functions-txid-snapshot">
11589     export server internal transaction information to user level.  The main
11590     use of these functions is to determine which transactions were committed
11591     between two snapshots.
11592    </para>
11593
11594    <table id="functions-txid-snapshot">
11595     <title>Transaction IDs and snapshots</title>
11596     <tgroup cols="3">
11597      <thead>
11598       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11599      </thead>
11600
11601      <tbody>
11602       <row>
11603        <entry><literal><function>txid_current</function>()</literal></entry>
11604        <entry><type>bigint</type></entry>
11605        <entry>get current transaction ID</entry>
11606       </row>
11607       <row>
11608        <entry><literal><function>txid_current_snapshot</function>()</literal></entry>
11609        <entry><type>txid_snapshot</type></entry>
11610        <entry>get current snapshot</entry>
11611       </row>
11612       <row>
11613        <entry><literal><function>txid_snapshot_xmin</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
11614        <entry><type>bigint</type></entry>
11615        <entry>get xmin of snapshot</entry>
11616       </row>
11617       <row>
11618        <entry><literal><function>txid_snapshot_xmax</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
11619        <entry><type>bigint</type></entry>
11620        <entry>get xmax of snapshot</entry>
11621       </row>
11622       <row>
11623        <entry><literal><function>txid_snapshot_xip</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
11624        <entry><type>setof bigint</type></entry>
11625        <entry>get in-progress transaction IDs in snapshot</entry>
11626       </row>
11627       <row>
11628        <entry><literal><function>txid_visible_in_snapshot</function>(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</literal></entry>
11629        <entry><type>boolean</type></entry>
11630        <entry>is transaction ID visible in snapshot?</entry>
11631       </row>
11632      </tbody>
11633     </tgroup>
11634    </table>
11635
11636    <para>
11637     The internal transaction ID type (<type>xid</>) is 32 bits wide and so
11638     it wraps around every 4 billion transactions.  However, these functions
11639     export a 64-bit format that is extended with an <quote>epoch</> counter
11640     so that it will not wrap around for the life of an installation.
11641     The data type used by these functions, <type>txid_snapshot</type>,
11642     stores information about transaction ID
11643     visibility at a particular moment in time.  Its components are
11644     described in <xref linkend="functions-txid-snapshot-parts">.
11645    </para>
11646
11647    <table id="functions-txid-snapshot-parts">
11648     <title>Snapshot components</title>
11649     <tgroup cols="2">
11650      <thead>
11651       <row>
11652        <entry>Name</entry>
11653        <entry>Description</entry>
11654       </row>
11655      </thead>
11656
11657      <tbody>
11658
11659       <row>
11660        <entry><type>xmin</type></entry>
11661        <entry>
11662          Earliest transaction ID (txid) that is still active.  All earlier
11663          transactions will either be committed and visible, or rolled
11664          back and dead.
11665        </entry>
11666       </row>
11667
11668       <row>
11669        <entry><type>xmax</type></entry>
11670        <entry>
11671         First as-yet-unassigned txid.  All txids later than this one are
11672         not yet started as of the time of the snapshot, and thus invisible.
11673        </entry>
11674       </row>
11675
11676       <row>
11677        <entry><type>xip_list</type></entry>
11678        <entry>
11679         Active txids at the time of the snapshot.  All of them are between
11680         <literal>xmin</> and <literal>xmax</>.  A txid that is
11681         <literal>xmin &lt;= txid &lt; xmax</literal> and not in this list was
11682         already completed at the time of the snapshot, and thus either visible
11683         or dead according to its commit status.
11684        </entry>
11685       </row>
11686
11687      </tbody>
11688     </tgroup>
11689    </table>
11690
11691    <para>
11692     <type>txid_snapshot</>'s textual representation is
11693     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
11694     For example <literal>10:20:10,14,15</literal> means
11695     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
11696    </para>
11697   </sect1>
11698
11699   <sect1 id="functions-admin">
11700    <title>System Administration Functions</title>
11701
11702    <para>
11703     <xref linkend="functions-admin-set-table"> shows the functions
11704     available to query and alter run-time configuration parameters.
11705    </para>
11706
11707    <table id="functions-admin-set-table">
11708     <title>Configuration Settings Functions</title>
11709     <tgroup cols="3">
11710      <thead>
11711       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11712      </thead>
11713
11714      <tbody>
11715       <row>
11716        <entry>
11717         <literal><function>current_setting</function>(<parameter>setting_name</parameter>)</literal>
11718        </entry>
11719        <entry><type>text</type></entry>
11720        <entry>current value of setting</entry>
11721       </row>
11722       <row>
11723        <entry>
11724         <literal><function>set_config(<parameter>setting_name</parameter>,
11725                              <parameter>new_value</parameter>,
11726                              <parameter>is_local</parameter>)</function></literal>
11727        </entry>
11728        <entry><type>text</type></entry>
11729        <entry>set parameter and return new value</entry>
11730       </row>
11731      </tbody>
11732     </tgroup>
11733    </table>
11734
11735    <indexterm>
11736     <primary>SET</primary>
11737    </indexterm>
11738
11739    <indexterm>
11740     <primary>SHOW</primary>
11741    </indexterm>
11742
11743    <indexterm>
11744     <primary>configuration</primary>
11745     <secondary sortas="server">of the server</secondary>
11746     <tertiary>functions</tertiary>
11747    </indexterm>
11748
11749    <para>
11750     The function <function>current_setting</function> yields the
11751     current value of the setting <parameter>setting_name</parameter>.
11752     It corresponds to the <acronym>SQL</acronym> command
11753     <command>SHOW</command>.  An example:
11754 <programlisting>
11755 SELECT current_setting('datestyle');
11756
11757  current_setting
11758 -----------------
11759  ISO, MDY
11760 (1 row)
11761 </programlisting>
11762    </para>
11763
11764    <para>
11765     <function>set_config</function> sets the parameter
11766     <parameter>setting_name</parameter> to
11767     <parameter>new_value</parameter>.  If
11768     <parameter>is_local</parameter> is <literal>true</literal>, the
11769     new value will only apply to the current transaction. If you want
11770     the new value to apply for the current session, use
11771     <literal>false</literal> instead. The function corresponds to the
11772     SQL command <command>SET</command>. An example:
11773 <programlisting>
11774 SELECT set_config('log_statement_stats', 'off', false);
11775
11776  set_config
11777 ------------
11778  off
11779 (1 row)
11780 </programlisting>
11781    </para>
11782
11783    <indexterm>
11784     <primary>pg_cancel_backend</primary>
11785    </indexterm>
11786    <indexterm>
11787     <primary>pg_reload_conf</primary>
11788    </indexterm>
11789    <indexterm>
11790     <primary>pg_rotate_logfile</primary>
11791    </indexterm>
11792
11793    <indexterm>
11794     <primary>signal</primary>
11795     <secondary sortas="backend">backend processes</secondary>
11796    </indexterm>
11797
11798    <para>
11799     The functions shown in <xref
11800     linkend="functions-admin-signal-table"> send control signals to
11801     other server processes.  Use of these functions is restricted
11802     to superusers.
11803    </para>
11804
11805    <table id="functions-admin-signal-table">
11806     <title>Server Signalling Functions</title>
11807     <tgroup cols="3">
11808      <thead>
11809       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
11810       </row>
11811      </thead>
11812
11813      <tbody>
11814       <row>
11815        <entry>
11816         <literal><function>pg_cancel_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
11817         </entry>
11818        <entry><type>boolean</type></entry>
11819        <entry>Cancel a backend's current query</entry>
11820       </row>
11821       <row>
11822        <entry>
11823         <literal><function>pg_reload_conf</function>()</literal>
11824         </entry>
11825        <entry><type>boolean</type></entry>
11826        <entry>Cause server processes to reload their configuration files</entry>
11827       </row>
11828       <row>
11829        <entry>
11830         <literal><function>pg_rotate_logfile</function>()</literal>
11831         </entry>
11832        <entry><type>boolean</type></entry>
11833        <entry>Rotate server's log file</entry>
11834       </row>
11835      </tbody>
11836     </tgroup>
11837    </table>
11838
11839    <para>
11840     Each of these functions returns <literal>true</literal> if
11841     successful and <literal>false</literal> otherwise.
11842    </para>
11843
11844    <para>
11845     <function>pg_cancel_backend</> sends a query cancel
11846     (<systemitem>SIGINT</>) signal to a backend process identified by
11847     process ID.  The process ID of an active backend can be found from
11848     the <structfield>procpid</structfield> column in the
11849     <structname>pg_stat_activity</structname> view, or by listing the
11850     <command>postgres</command> processes on the server with
11851     <application>ps</>.
11852    </para>
11853
11854    <para>
11855     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
11856     to the server, causing the configuration files
11857     to be reloaded by all server processes.
11858    </para>
11859
11860    <para>
11861     <function>pg_rotate_logfile</> signals the log-file manager to switch
11862     to a new output file immediately.  This works only when the built-in
11863     log collector is running, since otherwise there is no log-file manager 
11864     subprocess.
11865    </para>
11866
11867    <indexterm>
11868     <primary>pg_start_backup</primary>
11869    </indexterm>
11870    <indexterm>
11871     <primary>pg_stop_backup</primary>
11872    </indexterm>
11873    <indexterm>
11874     <primary>pg_switch_xlog</primary>
11875    </indexterm>
11876    <indexterm>
11877     <primary>pg_current_xlog_location</primary>
11878    </indexterm>
11879    <indexterm>
11880     <primary>pg_current_xlog_insert_location</primary>
11881    </indexterm>
11882    <indexterm>
11883     <primary>pg_xlogfile_name_offset</primary>
11884    </indexterm>
11885    <indexterm>
11886     <primary>pg_xlogfile_name</primary>
11887    </indexterm>
11888    <indexterm>
11889     <primary>backup</primary>
11890    </indexterm>
11891
11892    <para>
11893     The functions shown in <xref
11894     linkend="functions-admin-backup-table"> assist in making on-line backups.
11895     Use of the first three functions is restricted to superusers.
11896    </para>
11897
11898    <table id="functions-admin-backup-table">
11899     <title>Backup Control Functions</title>
11900     <tgroup cols="3">
11901      <thead>
11902       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
11903       </row>
11904      </thead>
11905
11906      <tbody>
11907       <row>
11908        <entry>
11909         <literal><function>pg_start_backup</function>(<parameter>label</> <type>text</>)</literal>
11910         </entry>
11911        <entry><type>text</type></entry>
11912        <entry>Set up for performing on-line backup</entry>
11913       </row>
11914       <row>
11915        <entry>
11916         <literal><function>pg_stop_backup</function>()</literal>
11917         </entry>
11918        <entry><type>text</type></entry>
11919        <entry>Finish performing on-line backup</entry>
11920       </row>
11921       <row>
11922        <entry>
11923         <literal><function>pg_switch_xlog</function>()</literal>
11924         </entry>
11925        <entry><type>text</type></entry>
11926        <entry>Force switch to a new transaction log file</entry>
11927       </row>
11928       <row>
11929        <entry>
11930         <literal><function>pg_current_xlog_location</function>()</literal>
11931         </entry>
11932        <entry><type>text</type></entry>
11933        <entry>Get current transaction log write location</entry>
11934       </row>
11935       <row>
11936        <entry>
11937         <literal><function>pg_current_xlog_insert_location</function>()</literal>
11938         </entry>
11939        <entry><type>text</type></entry>
11940        <entry>Get current transaction log insert location</entry>
11941       </row>
11942       <row>
11943        <entry>
11944         <literal><function>pg_xlogfile_name_offset</function>(<parameter>location</> <type>text</>)</literal>
11945         </entry>
11946        <entry><type>text</>, <type>integer</></entry>
11947        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
11948       </row>
11949       <row>
11950        <entry>
11951         <literal><function>pg_xlogfile_name</function>(<parameter>location</> <type>text</>)</literal>
11952         </entry>
11953        <entry><type>text</type></entry>
11954        <entry>Convert transaction log location string to file name</entry>
11955       </row>
11956      </tbody>
11957     </tgroup>
11958    </table>
11959
11960    <para>
11961     <function>pg_start_backup</> accepts a single parameter which is an
11962     arbitrary user-defined label for the backup.  (Typically this would be
11963     the name under which the backup dump file will be stored.)  The function
11964     writes a backup label file into the database cluster's data directory,
11965     and then returns the backup's starting transaction log location as text.  The user
11966     need not pay any attention to this result value, but it is provided in
11967     case it is of use. 
11968 <programlisting>
11969 postgres=# select pg_start_backup('label_goes_here');
11970  pg_start_backup
11971 -----------------
11972  0/D4445B8
11973 (1 row)
11974 </programlisting>
11975    </para>
11976
11977    <para>
11978     <function>pg_stop_backup</> removes the label file created by
11979     <function>pg_start_backup</>, and instead creates a backup history file in
11980     the transaction log archive area.  The history file includes the label given to
11981     <function>pg_start_backup</>, the starting and ending transaction log locations for
11982     the backup, and the starting and ending times of the backup.  The return
11983     value is the backup's ending transaction log location (which again might be of little
11984     interest).  After noting the ending location, the current transaction log insertion
11985     point is automatically advanced to the next transaction log file, so that the
11986     ending transaction log file can be archived immediately to complete the backup.
11987    </para>
11988
11989    <para>
11990     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the 
11991     current file to be archived (assuming you are using continuous archiving).
11992     The result is the ending transaction log location within the just-completed transaction log file.
11993     If there has been no transaction log activity since the last transaction log switch,
11994     <function>pg_switch_xlog</> does nothing and returns the end location
11995     of the previous transaction log file.
11996    </para>
11997
11998    <para>
11999     <function>pg_current_xlog_location</> displays the current transaction log write
12000     location in the same format used by the above functions.  Similarly,
12001     <function>pg_current_xlog_insert_location</> displays the current transaction log
12002     insertion point.  The insertion point is the <quote>logical</> end
12003     of the transaction log
12004     at any instant, while the write location is the end of what has actually
12005     been written out from the server's internal buffers.  The write location
12006     is the end of what can be examined from outside the server, and is usually
12007     what you want if you are interested in archiving partially-complete transaction log
12008     files.  The insertion point is made available primarily for server
12009     debugging purposes.  These are both read-only operations and do not
12010     require superuser permissions.
12011    </para>
12012
12013    <para>
12014     You can use <function>pg_xlogfile_name_offset</> to extract the
12015     corresponding transaction log file name and byte offset from the results of any of the
12016     above functions.  For example:
12017 <programlisting>
12018 postgres=# select * from pg_xlogfile_name_offset(pg_stop_backup());
12019         file_name         | file_offset 
12020 --------------------------+-------------
12021  00000001000000000000000D |     4039624
12022 (1 row)
12023 </programlisting>
12024     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
12025     When the given transaction log location is exactly at a transaction log file boundary, both
12026     these functions return the name of the preceding transaction log file.
12027     This is usually the desired behavior for managing transaction log archiving
12028     behavior, since the preceding file is the last one that currently
12029     needs to be archived.
12030    </para>
12031
12032    <para>
12033     For details about proper usage of these functions, see
12034     <xref linkend="continuous-archiving">.
12035    </para>
12036
12037    <para>
12038     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
12039     the actual disk space usage of database objects.
12040    </para>
12041
12042    <indexterm>
12043     <primary>pg_column_size</primary>
12044    </indexterm>
12045    <indexterm>
12046     <primary>pg_database_size</primary>
12047    </indexterm>
12048    <indexterm>
12049     <primary>pg_relation_size</primary>
12050    </indexterm>
12051    <indexterm>
12052     <primary>pg_size_pretty</primary>
12053    </indexterm>
12054    <indexterm>
12055     <primary>pg_tablespace_size</primary>
12056    </indexterm>
12057    <indexterm>
12058     <primary>pg_total_relation_size</primary>
12059    </indexterm>
12060
12061    <table id="functions-admin-dbsize">
12062     <title>Database Object Size Functions</title>
12063     <tgroup cols="3">
12064      <thead>
12065       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12066       </row>
12067      </thead>
12068
12069      <tbody>
12070       <row>
12071        <entry><function>pg_column_size</function>(<type>any</type>)</entry>
12072        <entry><type>int</type></entry>
12073        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
12074       </row>
12075       <row>
12076        <entry>
12077         <literal><function>pg_database_size</function>(<type>oid</type>)</literal>
12078         </entry>
12079        <entry><type>bigint</type></entry>
12080        <entry>Disk space used by the database with the specified OID</entry>
12081       </row>
12082       <row>
12083        <entry>
12084         <literal><function>pg_database_size</function>(<type>name</type>)</literal>
12085         </entry>
12086        <entry><type>bigint</type></entry>
12087        <entry>Disk space used by the database with the specified name</entry>
12088       </row>
12089       <row>
12090        <entry>
12091         <literal><function>pg_relation_size</function>(<type>oid</type>)</literal>
12092         </entry>
12093        <entry><type>bigint</type></entry>
12094        <entry>Disk space used by the table or index with the specified OID</entry>
12095       </row>
12096       <row>
12097        <entry>
12098         <literal><function>pg_relation_size</function>(<type>text</type>)</literal>
12099         </entry>
12100        <entry><type>bigint</type></entry>
12101        <entry>
12102         Disk space used by the table or index with the specified name.
12103         The table name can be qualified with a schema name
12104        </entry>
12105       </row>
12106       <row>
12107        <entry>
12108         <literal><function>pg_size_pretty</function>(<type>bigint</type>)</literal>
12109         </entry>
12110        <entry><type>text</type></entry>
12111        <entry>Converts a size in bytes into a human-readable format with size units</entry>
12112       </row>
12113       <row>
12114        <entry>
12115         <literal><function>pg_tablespace_size</function>(<type>oid</type>)</literal>
12116         </entry>
12117        <entry><type>bigint</type></entry>
12118        <entry>Disk space used by the tablespace with the specified OID</entry>
12119       </row>
12120       <row>
12121        <entry>
12122         <literal><function>pg_tablespace_size</function>(<type>name</type>)</literal>
12123         </entry>
12124        <entry><type>bigint</type></entry>
12125        <entry>Disk space used by the tablespace with the specified name</entry>
12126       </row>
12127       <row>
12128        <entry>
12129         <literal><function>pg_total_relation_size</function>(<type>oid</type>)</literal>
12130         </entry>
12131        <entry><type>bigint</type></entry>
12132        <entry>
12133         Total disk space used by the table with the specified OID,
12134         including indexes and toasted data
12135        </entry>
12136       </row>
12137       <row>
12138        <entry>
12139         <literal><function>pg_total_relation_size</function>(<type>text</type>)</literal>
12140         </entry>
12141        <entry><type>bigint</type></entry>
12142        <entry>
12143         Total disk space used by the table with the specified name,
12144         including indexes and toasted data.  The table name can be
12145         qualified with a schema name
12146        </entry>
12147       </row>
12148      </tbody>
12149     </tgroup>
12150    </table>
12151
12152    <para>
12153     <function>pg_column_size</> shows the space used to store any individual
12154     data value.
12155    </para>
12156
12157    <para>
12158     <function>pg_database_size</function> and <function>pg_tablespace_size</>
12159     accept the OID or name of a database or tablespace, and return the total
12160     disk space used therein.
12161    </para>
12162
12163    <para>
12164     <function>pg_relation_size</> accepts the OID or name of a table, index or
12165     toast table, and returns the size in bytes.
12166    </para>
12167
12168    <para>
12169     <function>pg_size_pretty</> can be used to format the result of one of
12170     the other functions in a human-readable way, using kB, MB, GB or TB as
12171     appropriate.
12172    </para>
12173
12174    <para>
12175     <function>pg_total_relation_size</> accepts the OID or name of a
12176     table or toast table, and returns the size in bytes of the data
12177     and all associated indexes and toast tables.
12178    </para>
12179
12180    <para>
12181     The functions shown in <xref
12182     linkend="functions-admin-genfile"> provide native file access to
12183     files on the machine hosting the server. Only files within the
12184     database cluster directory and the <varname>log_directory</> can be
12185     accessed.  Use a relative path for files within the cluster directory,
12186     and a path matching the <varname>log_directory</> configuration setting
12187     for log files.  Use of these functions is restricted to superusers.
12188    </para>
12189
12190    <table id="functions-admin-genfile">
12191     <title>Generic File Access Functions</title>
12192     <tgroup cols="3">
12193      <thead>
12194       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12195       </row>
12196      </thead>
12197
12198      <tbody>
12199       <row>
12200        <entry>
12201         <literal><function>pg_ls_dir</function>(<parameter>dirname</> <type>text</>)</literal>
12202        </entry>
12203        <entry><type>setof text</type></entry>
12204        <entry>List the contents of a directory</entry>
12205       </row>
12206       <row>
12207        <entry>
12208         <literal><function>pg_read_file</function>(<parameter>filename</> <type>text</>, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>)</literal>
12209        </entry>
12210        <entry><type>text</type></entry>
12211        <entry>Return the contents of a text file</entry>
12212       </row>
12213       <row>
12214        <entry>
12215         <literal><function>pg_stat_file</function>(<parameter>filename</> <type>text</>)</literal>
12216        </entry>
12217        <entry><type>record</type></entry>
12218        <entry>Return information about a file</entry>
12219       </row>
12220      </tbody>
12221     </tgroup>
12222    </table>
12223
12224    <indexterm>
12225     <primary>pg_ls_dir</primary>
12226    </indexterm>
12227    <para>
12228     <function>pg_ls_dir</> returns all the names in the specified
12229     directory, except the special entries <quote><literal>.</></> and
12230     <quote><literal>..</></>.
12231    </para>
12232
12233    <indexterm>
12234     <primary>pg_read_file</primary>
12235    </indexterm>
12236    <para>
12237     <function>pg_read_file</> returns part of a text file, starting
12238     at the given <parameter>offset</>, returning at most <parameter>length</>
12239     bytes (less if the end of file is reached first).  If <parameter>offset</>
12240     is negative, it is relative to the end of the file.
12241    </para>
12242
12243    <indexterm>
12244     <primary>pg_stat_file</primary>
12245    </indexterm>
12246    <para>
12247     <function>pg_stat_file</> returns a record containing the file
12248     size, last accessed time stamp, last modified time stamp,
12249     last file status change time stamp (Unix platforms only),
12250     file creation time stamp (Windows only), and a <type>boolean</type>
12251     indicating if it is a directory.  Typical usages include:
12252 <programlisting>
12253 SELECT * FROM pg_stat_file('filename');
12254 SELECT (pg_stat_file('filename')).modification;
12255 </programlisting>
12256    </para>
12257
12258    <para>
12259     The functions shown in <xref linkend="functions-advisory-locks"> manage
12260     advisory locks.  For details about proper usage of these functions, see
12261     <xref linkend="advisory-locks">.
12262    </para>
12263
12264    <table id="functions-advisory-locks">
12265     <title>Advisory Lock Functions</title>
12266     <tgroup cols="3">
12267      <thead>
12268       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12269       </row>
12270      </thead>
12271
12272      <tbody>
12273       <row>
12274        <entry>
12275         <literal><function>pg_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
12276        </entry>
12277        <entry><type>void</type></entry>
12278        <entry>Obtain exclusive advisory lock</entry>
12279       </row>
12280       <row>
12281        <entry>
12282         <literal><function>pg_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12283        </entry>
12284        <entry><type>void</type></entry>
12285        <entry>Obtain exclusive advisory lock</entry>
12286       </row>
12287
12288       <row>
12289        <entry>
12290         <literal><function>pg_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12291        </entry>
12292        <entry><type>void</type></entry>
12293        <entry>Obtain shared advisory lock</entry>
12294       </row>
12295       <row>
12296        <entry>
12297         <literal><function>pg_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12298        </entry>
12299        <entry><type>void</type></entry>
12300        <entry>Obtain shared advisory lock</entry>
12301       </row>
12302
12303       <row>
12304        <entry>
12305         <literal><function>pg_try_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
12306        </entry>
12307        <entry><type>boolean</type></entry>
12308        <entry>Obtain exclusive advisory lock if available</entry>
12309       </row>
12310       <row>
12311        <entry>
12312         <literal><function>pg_try_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12313        </entry>
12314        <entry><type>boolean</type></entry>
12315        <entry>Obtain exclusive advisory lock if available</entry>
12316       </row>
12317
12318       <row>
12319        <entry>
12320         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12321        </entry>
12322        <entry><type>boolean</type></entry>
12323        <entry>Obtain shared advisory lock if available</entry>
12324       </row>
12325       <row>
12326        <entry>
12327         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12328        </entry>
12329        <entry><type>boolean</type></entry>
12330        <entry>Obtain shared advisory lock if available</entry>
12331       </row>
12332
12333       <row>
12334        <entry>
12335         <literal><function>pg_advisory_unlock</function>(<parameter>key</> <type>bigint</>)</literal>
12336        </entry>
12337        <entry><type>boolean</type></entry>
12338        <entry>Release an exclusive advisory lock</entry>
12339       </row>
12340       <row>
12341        <entry>
12342         <literal><function>pg_advisory_unlock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12343        </entry>
12344        <entry><type>boolean</type></entry>
12345        <entry>Release an exclusive advisory lock</entry>
12346       </row>
12347
12348       <row>
12349        <entry>
12350         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12351        </entry>
12352        <entry><type>boolean</type></entry>
12353        <entry>Release a shared advisory lock</entry>
12354       </row>
12355       <row>
12356        <entry>
12357         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12358        </entry>
12359        <entry><type>boolean</type></entry>
12360        <entry>Release a shared advisory lock</entry>
12361       </row>
12362
12363       <row>
12364        <entry>
12365         <literal><function>pg_advisory_unlock_all</function>()</literal>
12366        </entry>
12367        <entry><type>void</type></entry>
12368        <entry>Release all advisory locks held by the current session</entry>
12369       </row>
12370
12371      </tbody>
12372     </tgroup>
12373    </table>
12374
12375    <indexterm>
12376     <primary>pg_advisory_lock</primary>
12377    </indexterm>
12378    <para>
12379     <function>pg_advisory_lock</> locks an application-defined resource,
12380     which can be identified either by a single 64-bit key value or two
12381     32-bit key values (note that these two key spaces do not overlap).  If
12382     another session already holds a lock on the same resource, the
12383     function will wait until the resource becomes available.  The lock
12384     is exclusive.  Multiple lock requests stack, so that if the same resource
12385     is locked three times it must be also unlocked three times to be
12386     released for other sessions' use.
12387    </para>
12388
12389    <indexterm>
12390     <primary>pg_advisory_lock_shared</primary>
12391    </indexterm>
12392    <para>
12393     <function>pg_advisory_lock_shared</> works the same as
12394     <function>pg_advisory_lock</>,
12395     except the lock can be shared with other sessions requesting shared locks.
12396     Only would-be exclusive lockers are locked out.
12397    </para>
12398
12399    <indexterm>
12400     <primary>pg_try_advisory_lock</primary>
12401    </indexterm>
12402    <para>
12403     <function>pg_try_advisory_lock</> is similar to
12404     <function>pg_advisory_lock</>, except the function will not wait for the
12405     lock to become available.  It will either obtain the lock immediately and
12406     return <literal>true</>, or return <literal>false</> if the lock cannot be
12407     acquired now.
12408    </para>
12409
12410    <indexterm>
12411     <primary>pg_try_advisory_lock_shared</primary>
12412    </indexterm>
12413    <para>
12414     <function>pg_try_advisory_lock_shared</> works the same as
12415     <function>pg_try_advisory_lock</>, except it attempts to acquire
12416     shared rather than exclusive lock.
12417    </para>
12418
12419    <indexterm>
12420     <primary>pg_advisory_unlock</primary>
12421    </indexterm>
12422    <para>
12423     <function>pg_advisory_unlock</> will release a previously-acquired
12424     exclusive advisory lock.  It
12425     will return <literal>true</> if the lock is successfully released.
12426     If the lock was in fact not held, it will return <literal>false</>,
12427     and in addition, an SQL warning will be raised by the server.
12428    </para>
12429
12430    <indexterm>
12431     <primary>pg_advisory_unlock_shared</primary>
12432    </indexterm>
12433    <para>
12434     <function>pg_advisory_unlock_shared</> works the same as
12435     <function>pg_advisory_unlock</>, 
12436     except to release a shared advisory lock.
12437    </para>
12438
12439    <indexterm>
12440     <primary>pg_advisory_unlock_all</primary>
12441    </indexterm>
12442    <para>
12443     <function>pg_advisory_unlock_all</> will release all advisory locks
12444     held by the current session.  (This function is implicitly invoked
12445     at session end, even if the client disconnects ungracefully.)
12446    </para>
12447
12448   </sect1>
12449
12450 </chapter>