]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
20443f2b288294bfa6b44f068308236114b7cc6e
[postgresql] / doc / src / sgml / func.sgml
1 <!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.458 2008/11/13 15:59:50 petere 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.  Because of this behavior,
348     <literal>IS NULL</> and <literal>IS NOT NULL</> do not always return
349     inverse results for row-valued expressions, i.e. a row-valued
350     expression that contains both NULL and non-null values will return false
351     for both tests.
352     This definition conforms to the SQL standard, and is a change from the
353     inconsistent behavior exhibited by <productname>PostgreSQL</productname>
354     versions prior to 8.2.
355    </para>
356   </note>
357
358    <para>
359     <indexterm>
360      <primary>IS DISTINCT FROM</primary>
361     </indexterm>
362     <indexterm>
363      <primary>IS NOT DISTINCT FROM</primary>
364     </indexterm>
365     The ordinary comparison operators yield null (signifying <quote>unknown</>)
366     when either input is null.  Another way to do comparisons is with the
367     <literal>IS <optional> NOT </> DISTINCT FROM</literal> construct:
368 <synopsis>
369 <replaceable>expression</replaceable> IS DISTINCT FROM <replaceable>expression</replaceable>
370 <replaceable>expression</replaceable> IS NOT DISTINCT FROM <replaceable>expression</replaceable>
371 </synopsis>
372     For non-null inputs, <literal>IS DISTINCT FROM</literal> is
373     the same as the <literal>&lt;&gt;</> operator.  However, when both
374     inputs are null it will return false, and when just one input is
375     null it will return true.  Similarly, <literal>IS NOT DISTINCT
376     FROM</literal> is identical to <literal>=</literal> for non-null
377     inputs, but it returns true when both inputs are null, and false when only
378     one input is null. Thus, these constructs effectively act as though null
379     were a normal data value, rather than <quote>unknown</>.
380    </para>
381
382    <para>
383     <indexterm>
384      <primary>IS TRUE</primary>
385     </indexterm>
386     <indexterm>
387      <primary>IS NOT TRUE</primary>
388     </indexterm>
389     <indexterm>
390      <primary>IS FALSE</primary>
391     </indexterm>
392     <indexterm>
393      <primary>IS NOT FALSE</primary>
394     </indexterm>
395     <indexterm>
396      <primary>IS UNKNOWN</primary>
397     </indexterm>
398     <indexterm>
399      <primary>IS NOT UNKNOWN</primary>
400     </indexterm>
401     Boolean values can also be tested using the constructs
402 <synopsis>
403 <replaceable>expression</replaceable> IS TRUE
404 <replaceable>expression</replaceable> IS NOT TRUE
405 <replaceable>expression</replaceable> IS FALSE
406 <replaceable>expression</replaceable> IS NOT FALSE
407 <replaceable>expression</replaceable> IS UNKNOWN
408 <replaceable>expression</replaceable> IS NOT UNKNOWN
409 </synopsis>
410     These will always return true or false, never a null value, even when the
411     operand is null.
412     A null input is treated as the logical value <quote>unknown</>.
413     Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
414     effectively the same as <literal>IS NULL</literal> and
415     <literal>IS NOT NULL</literal>, respectively, except that the input
416     expression must be of Boolean type.
417    </para>
418  
419 <!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
420    <para>
421     <indexterm>
422      <primary>IS OF</primary>
423     </indexterm>
424     <indexterm>
425      <primary>IS NOT OF</primary>
426     </indexterm>
427     It is possible to check the data type of an expression using the
428     constructs
429 <synopsis>
430 <replaceable>expression</replaceable> IS OF (typename, ...)
431 <replaceable>expression</replaceable> IS NOT OF (typename, ...)
432 </synopsis>
433     They return a boolean value based on whether the expression's data
434     type is one of the listed data types.
435    </para>
436 -->
437
438   </sect1>
439
440   <sect1 id="functions-math">
441    <title>Mathematical Functions and Operators</title>
442
443    <para>
444     Mathematical operators are provided for many
445     <productname>PostgreSQL</productname> types. For types without
446     common mathematical conventions for all possible permutations 
447     (e.g., date/time types) we
448     describe the actual behavior in subsequent sections.
449    </para>
450
451    <para>
452     <xref linkend="functions-math-op-table"> shows the available mathematical operators.
453    </para>
454
455    <table id="functions-math-op-table">
456     <title>Mathematical Operators</title>
457
458     <tgroup cols="4">
459      <thead>
460       <row>
461        <entry>Operator</entry>
462        <entry>Description</entry>
463        <entry>Example</entry>
464        <entry>Result</entry>
465       </row>
466      </thead>
467
468      <tbody>
469       <row>
470        <entry> <literal>+</literal> </entry>
471        <entry>addition</entry>
472        <entry><literal>2 + 3</literal></entry>
473        <entry><literal>5</literal></entry>
474       </row>
475
476       <row>
477        <entry> <literal>-</literal> </entry>
478        <entry>subtraction</entry>
479        <entry><literal>2 - 3</literal></entry>
480        <entry><literal>-1</literal></entry>
481       </row>
482
483       <row>
484        <entry> <literal>*</literal> </entry>
485        <entry>multiplication</entry>
486        <entry><literal>2 * 3</literal></entry>
487        <entry><literal>6</literal></entry>
488       </row>
489
490       <row>
491        <entry> <literal>/</literal> </entry>
492        <entry>division (integer division truncates results)</entry>
493        <entry><literal>4 / 2</literal></entry>
494        <entry><literal>2</literal></entry>
495       </row>
496
497       <row>
498        <entry> <literal>%</literal> </entry>
499        <entry>modulo (remainder)</entry>
500        <entry><literal>5 % 4</literal></entry>
501        <entry><literal>1</literal></entry>
502       </row>
503
504       <row>
505        <entry> <literal>^</literal> </entry>
506        <entry>exponentiation</entry>
507        <entry><literal>2.0 ^ 3.0</literal></entry>
508        <entry><literal>8</literal></entry>
509       </row>
510
511       <row>
512        <entry> <literal>|/</literal> </entry>
513        <entry>square root</entry>
514        <entry><literal>|/ 25.0</literal></entry>
515        <entry><literal>5</literal></entry>
516       </row>
517
518       <row>
519        <entry> <literal>||/</literal> </entry>
520        <entry>cube root</entry>
521        <entry><literal>||/ 27.0</literal></entry>
522        <entry><literal>3</literal></entry>
523       </row>
524
525       <row>
526        <entry> <literal>!</literal> </entry>
527        <entry>factorial</entry>
528        <entry><literal>5 !</literal></entry>
529        <entry><literal>120</literal></entry>
530       </row>
531
532       <row>
533        <entry> <literal>!!</literal> </entry>
534        <entry>factorial (prefix operator)</entry>
535        <entry><literal>!! 5</literal></entry>
536        <entry><literal>120</literal></entry>
537       </row>
538
539       <row>
540        <entry> <literal>@</literal> </entry>
541        <entry>absolute value</entry>
542        <entry><literal>@ -5.0</literal></entry>
543        <entry><literal>5</literal></entry>
544       </row>
545
546       <row>
547        <entry> <literal>&amp;</literal> </entry>
548        <entry>bitwise AND</entry>
549        <entry><literal>91 &amp; 15</literal></entry>
550        <entry><literal>11</literal></entry>
551       </row>
552
553       <row>
554        <entry> <literal>|</literal> </entry>
555        <entry>bitwise OR</entry>
556        <entry><literal>32 | 3</literal></entry>
557        <entry><literal>35</literal></entry>
558       </row>
559
560       <row>
561        <entry> <literal>#</literal> </entry>
562        <entry>bitwise XOR</entry>
563        <entry><literal>17 # 5</literal></entry>
564        <entry><literal>20</literal></entry>
565       </row>
566
567       <row>
568        <entry> <literal>~</literal> </entry>
569        <entry>bitwise NOT</entry>
570        <entry><literal>~1</literal></entry>
571        <entry><literal>-2</literal></entry>
572       </row>
573
574       <row>
575        <entry> <literal>&lt;&lt;</literal> </entry>
576        <entry>bitwise shift left</entry>
577        <entry><literal>1 &lt;&lt; 4</literal></entry>
578        <entry><literal>16</literal></entry>
579       </row>
580
581       <row>
582        <entry> <literal>&gt;&gt;</literal> </entry>
583        <entry>bitwise shift right</entry>
584        <entry><literal>8 &gt;&gt; 2</literal></entry>
585        <entry><literal>2</literal></entry>
586       </row>
587
588      </tbody>
589     </tgroup>
590    </table>
591
592    <para>
593     The bitwise operators work only on integral data types, whereas
594     the others are available for all numeric data types.  The bitwise
595     operators are also available for the bit
596     string types <type>bit</type> and <type>bit varying</type>, as
597     shown in <xref linkend="functions-bit-string-op-table">.
598    </para>
599
600   <para>
601    <xref linkend="functions-math-func-table"> shows the available
602    mathematical functions.  In the table, <literal>dp</literal>
603    indicates <type>double precision</type>.  Many of these functions
604    are provided in multiple forms with different argument types.
605    Except where noted, any given form of a function returns the same
606    data type as its argument.
607    The functions working with <type>double precision</type> data are mostly
608    implemented on top of the host system's C library; accuracy and behavior in
609    boundary cases can therefore vary depending on the host system.
610   </para>
611
612    <indexterm>
613     <primary>abs</primary>
614    </indexterm>
615    <indexterm>
616     <primary>cbrt</primary>
617    </indexterm>
618    <indexterm>
619     <primary>ceiling</primary>
620    </indexterm>
621    <indexterm>
622     <primary>degrees</primary>
623    </indexterm>
624    <indexterm>
625     <primary>div</primary>
626    </indexterm>
627    <indexterm>
628     <primary>exp</primary>
629    </indexterm>
630    <indexterm>
631     <primary>floor</primary>
632    </indexterm>
633    <indexterm>
634     <primary>ln</primary>
635    </indexterm>
636    <indexterm>
637     <primary>log</primary>
638    </indexterm>
639    <indexterm>
640     <primary>mod</primary>
641    </indexterm>
642    <indexterm>
643     <primary>pi</primary>
644    </indexterm>
645    <indexterm>
646     <primary>power</primary>
647    </indexterm>
648    <indexterm>
649     <primary>radians</primary>
650    </indexterm>
651    <indexterm>
652     <primary>random</primary>
653    </indexterm>
654    <indexterm>
655     <primary>round</primary>
656    </indexterm>
657    <indexterm>
658     <primary>setseed</primary>
659    </indexterm>
660    <indexterm>
661     <primary>sign</primary>
662    </indexterm>
663    <indexterm>
664     <primary>sqrt</primary>
665    </indexterm>
666    <indexterm>
667     <primary>trunc</primary>
668    </indexterm>
669    <indexterm>
670     <primary>width_bucket</primary>
671    </indexterm>
672
673    <table id="functions-math-func-table">
674     <title>Mathematical Functions</title>
675     <tgroup cols="5">
676      <thead>
677       <row>
678        <entry>Function</entry>
679        <entry>Return Type</entry>
680        <entry>Description</entry>
681        <entry>Example</entry>
682        <entry>Result</entry>
683       </row>
684      </thead>
685
686      <tbody>
687       <row>
688        <entry><literal><function>abs</>(<replaceable>x</replaceable>)</literal></entry>
689        <entry>(same as <replaceable>x</>)</entry>
690        <entry>absolute value</entry>
691        <entry><literal>abs(-17.4)</literal></entry>
692        <entry><literal>17.4</literal></entry>
693       </row>
694
695       <row>
696        <entry><literal><function>cbrt</function>(<type>dp</type>)</literal></entry>
697        <entry><type>dp</type></entry>
698        <entry>cube root</entry>
699        <entry><literal>cbrt(27.0)</literal></entry>
700        <entry><literal>3</literal></entry>
701       </row>
702
703       <row>
704        <entry><literal><function>ceil</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
705        <entry>(same as input)</entry>
706        <entry>smallest integer not less than argument</entry>
707        <entry><literal>ceil(-42.8)</literal></entry>
708        <entry><literal>-42</literal></entry>
709       </row>
710
711       <row>
712        <entry><literal><function>ceiling</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
713        <entry>(same as input)</entry>
714        <entry>smallest integer not less than argument (alias for <function>ceil</function>)</entry>
715        <entry><literal>ceiling(-95.3)</literal></entry>
716        <entry><literal>-95</literal></entry>
717       </row>
718
719       <row>
720        <entry><literal><function>degrees</function>(<type>dp</type>)</literal></entry>
721        <entry><type>dp</type></entry>
722        <entry>radians to degrees</entry>
723        <entry><literal>degrees(0.5)</literal></entry>
724        <entry><literal>28.6478897565412</literal></entry>
725       </row>
726
727       <row>
728        <entry><literal><function>div</function>(<parameter>y</parameter> <type>numeric</>,
729         <parameter>x</parameter> <type>numeric</>)</literal></entry>
730        <entry><type>numeric</></entry>
731        <entry>integer quotient of <parameter>y</parameter>/<parameter>x</parameter></entry>
732        <entry><literal>div(9,4)</literal></entry>
733        <entry><literal>2</literal></entry>
734       </row>
735
736       <row>
737        <entry><literal><function>exp</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
738        <entry>(same as input)</entry>
739        <entry>exponential</entry>
740        <entry><literal>exp(1.0)</literal></entry>
741        <entry><literal>2.71828182845905</literal></entry>
742       </row>
743
744       <row>
745        <entry><literal><function>floor</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
746        <entry>(same as input)</entry>
747        <entry>largest integer not greater than argument</entry>
748        <entry><literal>floor(-42.8)</literal></entry>
749        <entry><literal>-43</literal></entry>
750       </row>
751
752       <row>
753        <entry><literal><function>ln</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
754        <entry>(same as input)</entry>
755        <entry>natural logarithm</entry>
756        <entry><literal>ln(2.0)</literal></entry>
757        <entry><literal>0.693147180559945</literal></entry>
758       </row>
759
760       <row>
761        <entry><literal><function>log</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
762        <entry>(same as input)</entry>
763        <entry>base 10 logarithm</entry>
764        <entry><literal>log(100.0)</literal></entry>
765        <entry><literal>2</literal></entry>
766       </row>
767
768       <row>
769        <entry><literal><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
770         <parameter>x</parameter> <type>numeric</type>)</literal></entry>
771        <entry><type>numeric</type></entry>
772        <entry>logarithm to base <parameter>b</parameter></entry>
773        <entry><literal>log(2.0, 64.0)</literal></entry>
774        <entry><literal>6.0000000000</literal></entry>
775       </row>
776
777       <row>
778        <entry><literal><function>mod</function>(<parameter>y</parameter>,
779         <parameter>x</parameter>)</literal></entry>
780        <entry>(same as argument types)</entry>
781        <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
782        <entry><literal>mod(9,4)</literal></entry>
783        <entry><literal>1</literal></entry>
784       </row>
785
786       <row>
787        <entry><literal><function>pi</function>()</literal></entry>
788        <entry><type>dp</type></entry>
789        <entry><quote>&pi;</quote> constant</entry>
790        <entry><literal>pi()</literal></entry>
791        <entry><literal>3.14159265358979</literal></entry>
792       </row>
793
794       <row>
795        <entry><literal><function>power</function>(<parameter>a</parameter> <type>dp</type>,
796         <parameter>b</parameter> <type>dp</type>)</literal></entry>
797        <entry><type>dp</type></entry>
798        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
799        <entry><literal>power(9.0, 3.0)</literal></entry>
800        <entry><literal>729</literal></entry>
801       </row>
802
803       <row>
804        <entry><literal><function>power</function>(<parameter>a</parameter> <type>numeric</type>,
805         <parameter>b</parameter> <type>numeric</type>)</literal></entry>
806        <entry><type>numeric</type></entry>
807        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
808        <entry><literal>power(9.0, 3.0)</literal></entry>
809        <entry><literal>729</literal></entry>
810       </row>
811
812       <row>
813        <entry><literal><function>radians</function>(<type>dp</type>)</literal></entry>
814        <entry><type>dp</type></entry>
815        <entry>degrees to radians</entry>
816        <entry><literal>radians(45.0)</literal></entry>
817        <entry><literal>0.785398163397448</literal></entry>
818       </row>
819
820       <row>
821        <entry><literal><function>random</function>()</literal></entry>
822        <entry><type>dp</type></entry>
823        <entry>random value between 0.0 and 1.0</entry>
824        <entry><literal>random()</literal></entry>
825        <entry></entry>
826       </row>
827
828       <row>
829        <entry><literal><function>round</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
830        <entry>(same as input)</entry>
831        <entry>round to nearest integer</entry>
832        <entry><literal>round(42.4)</literal></entry>
833        <entry><literal>42</literal></entry>
834       </row>
835
836       <row>
837        <entry><literal><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
838        <entry><type>numeric</type></entry>
839        <entry>round to <parameter>s</parameter> decimal places</entry>
840        <entry><literal>round(42.4382, 2)</literal></entry>
841        <entry><literal>42.44</literal></entry>
842       </row>
843
844       <row>
845        <entry><literal><function>setseed</function>(<type>dp</type>)</literal></entry>
846        <entry><type>void</type></entry>
847        <entry>set seed for subsequent <literal>random()</literal> calls (value between -1.0 and 1.0)</entry>
848        <entry><literal>setseed(0.54823)</literal></entry>
849        <entry></entry>
850       </row>
851
852       <row>
853        <entry><literal><function>sign</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
854        <entry>(same as input)</entry>
855        <entry>sign of the argument (-1, 0, +1)</entry>
856        <entry><literal>sign(-8.4)</literal></entry>
857        <entry><literal>-1</literal></entry>
858       </row>
859
860       <row>
861        <entry><literal><function>sqrt</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
862        <entry>(same as input)</entry>
863        <entry>square root</entry>
864        <entry><literal>sqrt(2.0)</literal></entry>
865        <entry><literal>1.4142135623731</literal></entry>
866       </row>
867
868       <row>
869        <entry><literal><function>trunc</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
870        <entry>(same as input)</entry>
871        <entry>truncate toward zero</entry>
872        <entry><literal>trunc(42.8)</literal></entry>
873        <entry><literal>42</literal></entry>
874       </row>
875
876       <row>
877        <entry><literal><function>trunc</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
878        <entry><type>numeric</type></entry>
879        <entry>truncate to <parameter>s</parameter> decimal places</entry>
880        <entry><literal>trunc(42.4382, 2)</literal></entry>
881        <entry><literal>42.43</literal></entry>
882       </row>
883
884       <row>
885        <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>
886        <entry><type>int</type></entry>
887        <entry>return the bucket to which <parameter>operand</> would
888        be assigned in an equidepth histogram with <parameter>count</>
889        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
890        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
891        <entry><literal>3</literal></entry>
892       </row>
893
894       <row>
895        <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>
896        <entry><type>int</type></entry>
897        <entry>return the bucket to which <parameter>operand</> would
898        be assigned in an equidepth histogram with <parameter>count</>
899        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
900        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
901        <entry><literal>3</literal></entry>
902       </row>
903      </tbody>
904     </tgroup>
905    </table>
906
907   <para>
908    Finally, <xref linkend="functions-math-trig-table"> shows the
909    available trigonometric functions.  All trigonometric functions
910    take arguments and return values of type <type>double
911    precision</type>.
912   </para>
913
914    <indexterm>
915     <primary>acos</primary>
916    </indexterm>
917    <indexterm>
918     <primary>asin</primary>
919    </indexterm>
920    <indexterm>
921     <primary>atan</primary>
922    </indexterm>
923    <indexterm>
924     <primary>atan2</primary>
925    </indexterm>
926    <indexterm>
927     <primary>cos</primary>
928    </indexterm>
929    <indexterm>
930     <primary>cot</primary>
931    </indexterm>
932    <indexterm>
933     <primary>sin</primary>
934    </indexterm>
935    <indexterm>
936     <primary>tan</primary>
937    </indexterm>
938
939    <table id="functions-math-trig-table">
940     <title>Trigonometric Functions</title>
941
942     <tgroup cols="2">
943      <thead>
944       <row>
945        <entry>Function</entry>
946        <entry>Description</entry>
947       </row>
948      </thead>
949
950      <tbody>
951       <row>
952        <entry><literal><function>acos</function>(<replaceable>x</replaceable>)</literal></entry>
953        <entry>inverse cosine</entry>
954       </row>
955
956       <row>
957        <entry><literal><function>asin</function>(<replaceable>x</replaceable>)</literal></entry>
958        <entry>inverse sine</entry>
959       </row>
960
961       <row>
962        <entry><literal><function>atan</function>(<replaceable>x</replaceable>)</literal></entry>
963        <entry>inverse tangent</entry>
964       </row>
965
966       <row>
967        <entry><literal><function>atan2</function>(<replaceable>y</replaceable>,
968         <replaceable>x</replaceable>)</literal></entry>
969        <entry>inverse tangent of
970         <literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
971       </row>
972
973       <row>
974        <entry><literal><function>cos</function>(<replaceable>x</replaceable>)</literal></entry>
975        <entry>cosine</entry>
976       </row>
977
978       <row>
979        <entry><literal><function>cot</function>(<replaceable>x</replaceable>)</literal></entry>
980        <entry>cotangent</entry>
981       </row>
982
983       <row>
984        <entry><literal><function>sin</function>(<replaceable>x</replaceable>)</literal></entry>
985        <entry>sine</entry>
986       </row>
987
988       <row>
989        <entry><literal><function>tan</function>(<replaceable>x</replaceable>)</literal></entry>
990        <entry>tangent</entry>
991       </row>
992      </tbody>
993     </tgroup>
994    </table>
995
996   </sect1>
997
998
999   <sect1 id="functions-string">
1000    <title>String Functions and Operators</title>
1001
1002    <para>
1003     This section describes functions and operators for examining and
1004     manipulating string values.  Strings in this context include values
1005     of the types <type>character</type>, <type>character varying</type>,
1006     and <type>text</type>.  Unless otherwise noted, all
1007     of the functions listed below work on all of these types, but be
1008     wary of potential effects of automatic space-padding when using the
1009     <type>character</type> type.  Some functions also exist
1010     natively for the bit-string types.
1011    </para>
1012
1013    <para>
1014     <acronym>SQL</acronym> defines some string functions with a special syntax
1015     wherein certain key words rather than commas are used to separate the
1016     arguments.  Details are in <xref linkend="functions-string-sql">.
1017     These functions are also implemented using the regular syntax for
1018     function invocation.  (See <xref linkend="functions-string-other">.)
1019    </para>
1020
1021    <note>
1022     <para>
1023      Before <productname>PostgreSQL</productname> 8.3, these functions would
1024      silently accept values of several non-string data types as well, due to
1025      the presence of implicit coercions from those data types to
1026      <type>text</>.  Those coercions have been removed because they frequently
1027      caused surprising behaviors.  However, the string concatenation operator
1028      (<literal>||</>) still accepts non-string input, so long as at least one
1029      input is of a string type, as shown in <xref
1030      linkend="functions-string-sql">.  For other cases, insert an explicit
1031      coercion to <type>text</> if you need to duplicate the previous behavior.
1032     </para>
1033    </note>
1034
1035    <indexterm>
1036     <primary>bit_length</primary>
1037    </indexterm>
1038    <indexterm>
1039     <primary>char_length</primary>
1040    </indexterm>
1041    <indexterm>
1042     <primary>lower</primary>
1043    </indexterm>
1044    <indexterm>
1045     <primary>octet_length</primary>
1046    </indexterm>
1047    <indexterm>
1048     <primary>overlay</primary>
1049    </indexterm>
1050    <indexterm>
1051     <primary>position</primary>
1052    </indexterm>
1053    <indexterm>
1054     <primary>substring</primary>
1055    </indexterm>
1056    <indexterm>
1057     <primary>trim</primary>
1058    </indexterm>
1059    <indexterm>
1060     <primary>upper</primary>
1061    </indexterm>
1062
1063    <table id="functions-string-sql">
1064     <title><acronym>SQL</acronym> String Functions and Operators</title>
1065     <tgroup cols="5">
1066      <thead>
1067       <row>
1068        <entry>Function</entry>
1069        <entry>Return Type</entry>
1070        <entry>Description</entry>
1071        <entry>Example</entry>
1072        <entry>Result</entry>  
1073       </row>
1074      </thead>
1075
1076      <tbody>
1077       <row>
1078        <entry><literal><parameter>string</parameter> <literal>||</literal>
1079         <parameter>string</parameter></literal></entry>
1080        <entry> <type>text</type> </entry>
1081        <entry>
1082         String concatenation
1083         <indexterm>
1084          <primary>character string</primary>
1085          <secondary>concatenation</secondary>
1086         </indexterm>
1087        </entry>
1088        <entry><literal>'Post' || 'greSQL'</literal></entry>
1089        <entry><literal>PostgreSQL</literal></entry>
1090       </row>
1091
1092       <row>
1093        <entry>
1094         <literal><parameter>string</parameter> <literal>||</literal>
1095         <parameter>non-string</parameter></literal>
1096         or
1097         <literal><parameter>non-string</parameter> <literal>||</literal>
1098         <parameter>string</parameter></literal>
1099        </entry>
1100        <entry> <type>text</type> </entry>
1101        <entry>
1102         String concatenation with one non-string input
1103        </entry>
1104        <entry><literal>'Value: ' || 42</literal></entry>
1105        <entry><literal>Value: 42</literal></entry>
1106       </row>
1107
1108       <row>
1109        <entry><literal><function>bit_length</function>(<parameter>string</parameter>)</literal></entry>
1110        <entry><type>int</type></entry>
1111        <entry>Number of bits in string</entry>
1112        <entry><literal>bit_length('jose')</literal></entry>
1113        <entry><literal>32</literal></entry>
1114       </row>
1115
1116       <row>
1117        <entry><literal><function>char_length</function>(<parameter>string</parameter>)</literal> or <literal><function>character_length</function>(<parameter>string</parameter>)</literal></entry>
1118        <entry><type>int</type></entry>
1119        <entry>
1120         Number of characters in string
1121         <indexterm>
1122          <primary>character string</primary>
1123          <secondary>length</secondary>
1124         </indexterm>
1125         <indexterm>
1126          <primary>length</primary>
1127          <secondary sortas="character string">of a character string</secondary>
1128          <see>character string, length</see>
1129         </indexterm>
1130        </entry>
1131        <entry><literal>char_length('jose')</literal></entry>
1132        <entry><literal>4</literal></entry>
1133       </row>
1134
1135       <row>
1136        <entry><literal><function>lower</function>(<parameter>string</parameter>)</literal></entry>
1137        <entry><type>text</type></entry>
1138        <entry>Convert string to lower case</entry>
1139        <entry><literal>lower('TOM')</literal></entry>
1140        <entry><literal>tom</literal></entry>
1141       </row>
1142
1143       <row>
1144        <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
1145        <entry><type>int</type></entry>
1146        <entry>Number of bytes in string</entry>
1147        <entry><literal>octet_length('jose')</literal></entry>
1148        <entry><literal>4</literal></entry>
1149       </row>
1150
1151       <row>
1152        <entry><literal><function>overlay</function>(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</literal></entry>
1153        <entry><type>text</type></entry>
1154        <entry>
1155         Replace substring
1156        </entry>
1157        <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
1158        <entry><literal>Thomas</literal></entry>
1159       </row>
1160
1161       <row>
1162        <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
1163        <entry><type>int</type></entry>
1164        <entry>Location of specified substring</entry>
1165        <entry><literal>position('om' in 'Thomas')</literal></entry>
1166        <entry><literal>3</literal></entry>
1167       </row>
1168
1169       <row>
1170        <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
1171        <entry><type>text</type></entry>
1172        <entry>
1173         Extract substring
1174        </entry>
1175        <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
1176        <entry><literal>hom</literal></entry>
1177       </row>
1178
1179       <row>
1180        <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</literal></entry>
1181        <entry><type>text</type></entry>
1182        <entry>
1183         Extract substring matching POSIX regular expression. See
1184         <xref linkend="functions-matching"> for more information on pattern
1185         matching.
1186        </entry>
1187        <entry><literal>substring('Thomas' from '...$')</literal></entry>
1188        <entry><literal>mas</literal></entry>
1189       </row>
1190
1191       <row>
1192        <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</literal></entry>
1193        <entry><type>text</type></entry>
1194        <entry>
1195         Extract substring matching <acronym>SQL</acronym> regular expression.
1196         See <xref linkend="functions-matching"> for more information on
1197         pattern matching.
1198        </entry>
1199        <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
1200        <entry><literal>oma</literal></entry>
1201       </row>
1202
1203       <row>
1204        <entry>
1205         <literal><function>trim</function>(<optional>leading | trailing | both</optional>
1206         <optional><parameter>characters</parameter></optional> from
1207         <parameter>string</parameter>)</literal>
1208        </entry>
1209        <entry><type>text</type></entry>
1210        <entry>
1211         Remove the longest string containing only the
1212         <parameter>characters</parameter> (a space by default) from the
1213         start/end/both ends of the <parameter>string</parameter>
1214        </entry>
1215        <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
1216        <entry><literal>Tom</literal></entry>
1217       </row>
1218
1219       <row>
1220        <entry><literal><function>upper</function>(<parameter>string</parameter>)</literal></entry>
1221        <entry><type>text</type></entry>
1222        <entry>Convert string to uppercase</entry>
1223        <entry><literal>upper('tom')</literal></entry>
1224        <entry><literal>TOM</literal></entry>
1225       </row>
1226      </tbody>
1227     </tgroup>
1228    </table>
1229
1230    <para>
1231     Additional string manipulation functions are available and are
1232     listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
1233     <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
1234    </para>
1235
1236    <indexterm>
1237     <primary>ascii</primary>
1238    </indexterm>
1239    <indexterm>
1240     <primary>btrim</primary>
1241    </indexterm>
1242    <indexterm>
1243     <primary>chr</primary>
1244    </indexterm>
1245    <indexterm>
1246     <primary>convert</primary>
1247    </indexterm>
1248    <indexterm>
1249     <primary>convert_from</primary>
1250    </indexterm>
1251    <indexterm>
1252     <primary>convert_to</primary>
1253    </indexterm>
1254    <indexterm>
1255     <primary>decode</primary>
1256    </indexterm>
1257    <indexterm>
1258     <primary>encode</primary>
1259    </indexterm>
1260    <indexterm>
1261     <primary>initcap</primary>
1262    </indexterm>
1263    <indexterm>
1264     <primary>lpad</primary>
1265    </indexterm>
1266    <indexterm>
1267     <primary>ltrim</primary>
1268    </indexterm>
1269    <indexterm>
1270     <primary>md5</primary>
1271    </indexterm>
1272    <indexterm>
1273     <primary>pg_client_encoding</primary>
1274    </indexterm>
1275    <indexterm>
1276     <primary>quote_ident</primary>
1277    </indexterm>
1278    <indexterm>
1279     <primary>quote_literal</primary>
1280    </indexterm>
1281    <indexterm>
1282     <primary>quote_nullable</primary>
1283    </indexterm>
1284    <indexterm>
1285     <primary>repeat</primary>
1286    </indexterm>
1287    <indexterm>
1288     <primary>replace</primary>
1289    </indexterm>
1290    <indexterm>
1291     <primary>rpad</primary>
1292    </indexterm>
1293    <indexterm>
1294     <primary>rtrim</primary>
1295    </indexterm>
1296    <indexterm>
1297     <primary>split_part</primary>
1298    </indexterm>
1299    <indexterm>
1300     <primary>strpos</primary>
1301    </indexterm>
1302    <indexterm>
1303     <primary>substr</primary>
1304    </indexterm>
1305    <indexterm>
1306     <primary>to_ascii</primary>
1307    </indexterm>
1308    <indexterm>
1309     <primary>to_hex</primary>
1310    </indexterm>
1311    <indexterm>
1312     <primary>translate</primary>
1313    </indexterm>
1314
1315    <table id="functions-string-other">
1316     <title>Other String Functions</title>
1317     <tgroup cols="5">
1318      <thead>
1319       <row>
1320        <entry>Function</entry>
1321        <entry>Return Type</entry>
1322        <entry>Description</entry>
1323        <entry>Example</entry>
1324        <entry>Result</entry>
1325       </row>
1326      </thead>
1327
1328      <tbody>
1329       <row>
1330        <entry><literal><function>ascii</function>(<parameter>string</parameter>)</literal></entry>
1331        <entry><type>int</type></entry>
1332        <entry>
1333         <acronym>ASCII</acronym> code of the first character of the
1334         argument.  For <acronym>UTF8</acronym> returns the Unicode code
1335         point of the character.  For other multibyte encodings. the
1336         argument must be a strictly <acronym>ASCII</acronym> character.
1337        </entry>
1338        <entry><literal>ascii('x')</literal></entry>
1339        <entry><literal>120</literal></entry>
1340       </row>
1341
1342       <row>
1343        <entry><literal><function>btrim</function>(<parameter>string</parameter> <type>text</type>
1344        <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal></entry>
1345        <entry><type>text</type></entry>
1346        <entry>
1347         Remove the longest string consisting only of characters
1348         in <parameter>characters</parameter> (a space by default)
1349         from the start and end of <parameter>string</parameter>
1350        </entry>
1351        <entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
1352        <entry><literal>trim</literal></entry>
1353       </row>
1354
1355       <row>
1356        <entry><literal><function>chr</function>(<type>int</type>)</literal></entry>
1357        <entry><type>text</type></entry>
1358        <entry>
1359         Character with the given code. For <acronym>UTF8</acronym> the
1360         argument is treated as a Unicode code point. For other multibyte
1361         encodings the argument must designate a strictly
1362         <acronym>ASCII</acronym> character.  The NULL (0) character is not
1363         allowed because text data types cannot store such bytes.
1364        </entry>
1365        <entry><literal>chr(65)</literal></entry>
1366        <entry><literal>A</literal></entry>
1367       </row>
1368
1369       <row>
1370        <entry>
1371         <literal><function>convert</function>(<parameter>string</parameter> <type>bytea</type>,
1372         <parameter>src_encoding</parameter> <type>name</type>,
1373         <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1374        </entry>
1375        <entry><type>bytea</type></entry>
1376        <entry>
1377         Convert string to <parameter>dest_encoding</parameter>.  The
1378         original encoding is specified by
1379         <parameter>src_encoding</parameter>. The
1380         <parameter>string</parameter> must be valid in this encoding.
1381         Conversions can be defined by <command>CREATE CONVERSION</command>.  
1382         Also there are some predefined conversions. See <xref
1383         linkend="conversion-names"> for available conversions.
1384        </entry>
1385        <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1386        <entry><literal>text_in_utf8</literal> represented in ISO 8859-1 encoding</entry>
1387       </row>
1388
1389       <row>
1390        <entry>
1391         <literal><function>convert_from</function>(<parameter>string</parameter> <type>bytea</type>,
1392         <parameter>src_encoding</parameter> <type>name</type>)</literal>
1393        </entry>
1394        <entry><type>text</type></entry>
1395        <entry>
1396         Convert string to the database encoding.  The original encoding
1397         is specified by <parameter>src_encoding</parameter>. The
1398         <parameter>string</parameter> must be valid in this encoding.
1399        </entry>
1400        <entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
1401        <entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
1402       </row>
1403
1404       <row>
1405        <entry>
1406         <literal><function>convert_to</function>(<parameter>string</parameter> <type>text</type>,
1407         <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1408        </entry>
1409        <entry><type>bytea</type></entry>
1410        <entry>
1411         Convert string to <parameter>dest_encoding</parameter>.
1412        </entry>
1413        <entry><literal>convert_to('some text', 'UTF8')</literal></entry>
1414        <entry><literal>some text</literal> represented in the UTF8 encoding</entry>
1415       </row>
1416
1417       <row>
1418        <entry>
1419         <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
1420         <parameter>type</parameter> <type>text</type>)</literal>
1421        </entry>
1422        <entry><type>bytea</type></entry>
1423        <entry>
1424         Decode binary data from <parameter>string</parameter> previously 
1425         encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
1426        </entry>
1427        <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
1428        <entry><literal>123\000\001</literal></entry>
1429       </row>       
1430
1431       <row>
1432        <entry>
1433         <literal><function>encode</function>(<parameter>data</parameter> <type>bytea</type>,
1434         <parameter>type</parameter> <type>text</type>)</literal>
1435        </entry>
1436        <entry><type>text</type></entry>
1437        <entry>
1438         Encode binary data to different representation.  Supported
1439         types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
1440         <literal>Escape</> merely outputs null bytes as <literal>\000</> and
1441         doubles backslashes.
1442        </entry>
1443        <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1444        <entry><literal>MTIzAAE=</literal></entry>
1445       </row>       
1446
1447       <row>
1448        <entry><literal><function>initcap</function>(<parameter>string</parameter>)</literal></entry>
1449        <entry><type>text</type></entry>
1450        <entry>
1451         Convert the first letter of each word to uppercase and the
1452         rest to lowercase. Words are sequences of alphanumeric
1453         characters separated by non-alphanumeric characters.
1454        </entry>
1455        <entry><literal>initcap('hi THOMAS')</literal></entry>
1456        <entry><literal>Hi Thomas</literal></entry>
1457       </row>
1458
1459       <row>
1460        <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
1461        <entry><type>int</type></entry>
1462        <entry>
1463         Number of characters in <parameter>string</parameter>
1464        </entry>
1465        <entry><literal>length('jose')</literal></entry>
1466        <entry><literal>4</literal></entry>
1467       </row>
1468
1469       <row>
1470        <entry><literal><function>length</function>(<parameter>string</parameter><type>bytea</type>,
1471         <parameter>encoding</parameter> <type>name</type> )</literal></entry>
1472        <entry><type>int</type></entry>
1473        <entry>
1474         Number of characters in <parameter>string</parameter> in the given
1475         <parameter>encoding</parameter>. The <parameter>string</parameter>
1476         must be valid in this encoding.
1477        </entry>
1478        <entry><literal>length('jose', 'UTF8')</literal></entry>
1479        <entry><literal>4</literal></entry>
1480       </row>
1481
1482       <row>
1483        <entry>
1484         <literal><function>lpad</function>(<parameter>string</parameter> <type>text</type>,
1485         <parameter>length</parameter> <type>int</type>
1486         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1487        </entry>
1488        <entry><type>text</type></entry>
1489        <entry>
1490         Fill up the <parameter>string</parameter> to length
1491         <parameter>length</parameter> by prepending the characters
1492         <parameter>fill</parameter> (a space by default).  If the
1493         <parameter>string</parameter> is already longer than
1494         <parameter>length</parameter> then it is truncated (on the
1495         right).
1496        </entry>
1497        <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1498        <entry><literal>xyxhi</literal></entry>
1499       </row>
1500
1501       <row>
1502        <entry><literal><function>ltrim</function>(<parameter>string</parameter> <type>text</type>
1503         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
1504        </entry>
1505        <entry><type>text</type></entry>
1506        <entry>
1507         Remove the longest string containing only characters from
1508         <parameter>characters</parameter> (a space by default) from the start of
1509         <parameter>string</parameter>
1510        </entry>
1511        <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
1512        <entry><literal>trim</literal></entry>
1513       </row>
1514
1515       <row>
1516        <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
1517        <entry><type>text</type></entry>
1518        <entry>
1519         Calculates the MD5 hash of <parameter>string</parameter>,
1520         returning the result in hexadecimal
1521        </entry>
1522        <entry><literal>md5('abc')</literal></entry>
1523        <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1524       </row>
1525
1526       <row>
1527        <entry><literal><function>pg_client_encoding</function>()</literal></entry>
1528        <entry><type>name</type></entry>
1529        <entry>
1530         Current client encoding name
1531        </entry>
1532        <entry><literal>pg_client_encoding()</literal></entry>
1533        <entry><literal>SQL_ASCII</literal></entry>
1534       </row>
1535
1536       <row>
1537        <entry><literal><function>quote_ident</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
1538        <entry><type>text</type></entry>
1539        <entry>
1540         Return the given string suitably quoted to be used as an identifier
1541         in an <acronym>SQL</acronym> statement string.
1542         Quotes are added only if necessary (i.e., if the string contains
1543         non-identifier characters or would be case-folded).
1544         Embedded quotes are properly doubled.
1545         See also <xref linkend="plpgsql-quote-literal-example">.
1546        </entry>
1547        <entry><literal>quote_ident('Foo bar')</literal></entry>
1548        <entry><literal>"Foo bar"</literal></entry>
1549       </row>
1550
1551       <row>
1552        <entry><literal><function>quote_literal</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
1553        <entry><type>text</type></entry>
1554        <entry>
1555         Return the given string suitably quoted to be used as a string literal
1556         in an <acronym>SQL</acronym> statement string.
1557         Embedded single-quotes and backslashes are properly doubled.
1558         Note that <function>quote_literal</function> returns null on null
1559         input; if the argument might be null,
1560         <function>quote_nullable</function> is often more suitable.
1561         See also <xref linkend="plpgsql-quote-literal-example">.
1562        </entry>
1563        <entry><literal>quote_literal('O\'Reilly')</literal></entry>
1564        <entry><literal>'O''Reilly'</literal></entry>
1565       </row>
1566
1567       <row>
1568        <entry><literal><function>quote_literal</function>(<parameter>value</parameter> <type>anyelement</type>)</literal></entry>
1569        <entry><type>text</type></entry>
1570        <entry>
1571         Coerce the given value to text and then quote it as a literal.
1572         Embedded single-quotes and backslashes are properly doubled.
1573        </entry>
1574        <entry><literal>quote_literal(42.5)</literal></entry>
1575        <entry><literal>'42.5'</literal></entry>
1576       </row>
1577
1578       <row>
1579        <entry><literal><function>quote_nullable</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
1580        <entry><type>text</type></entry>
1581        <entry>
1582         Return the given string suitably quoted to be used as a string literal
1583         in an <acronym>SQL</acronym> statement string; or, if the argument
1584         is null, return <literal>NULL</>.
1585         Embedded single-quotes and backslashes are properly doubled.
1586         See also <xref linkend="plpgsql-quote-literal-example">.
1587        </entry>
1588        <entry><literal>quote_nullable(NULL)</literal></entry>
1589        <entry><literal>NULL</literal></entry>
1590       </row>
1591
1592       <row>
1593        <entry><literal><function>quote_nullable</function>(<parameter>value</parameter> <type>anyelement</type>)</literal></entry>
1594        <entry><type>text</type></entry>
1595        <entry>
1596         Coerce the given value to text and then quote it as a literal;
1597         or, if the argument is null, return <literal>NULL</>.
1598         Embedded single-quotes and backslashes are properly doubled.
1599        </entry>
1600        <entry><literal>quote_nullable(42.5)</literal></entry>
1601        <entry><literal>'42.5'</literal></entry>
1602       </row>
1603
1604       <row>
1605        <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>
1606        <entry><type>setof text[]</type></entry>
1607        <entry>
1608         Return all captured substrings resulting from matching a POSIX regular
1609         expression against the <parameter>string</parameter>. See
1610         <xref linkend="functions-posix-regexp"> for more information.
1611        </entry>
1612        <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
1613        <entry><literal>{bar,beque}</literal></entry>
1614       </row>
1615
1616       <row>
1617        <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>
1618        <entry><type>text</type></entry>
1619        <entry>
1620         Replace substring(s) matching a POSIX regular expression. See
1621         <xref linkend="functions-posix-regexp"> for more information.
1622        </entry>
1623        <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
1624        <entry><literal>ThM</literal></entry>
1625       </row>
1626
1627       <row>
1628        <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>
1629        <entry><type>text[]</type></entry>
1630        <entry>
1631         Split <parameter>string</parameter> using a POSIX regular expression as
1632         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1633         information.
1634        </entry>
1635        <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
1636        <entry><literal>{hello,world}</literal></entry>
1637       </row>
1638
1639       <row>
1640        <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>
1641        <entry><type>setof text</type></entry>
1642        <entry>
1643         Split <parameter>string</parameter> using a POSIX regular expression as
1644         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1645         information.
1646        </entry>
1647        <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
1648        <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
1649       </row>
1650
1651       <row>
1652        <entry><literal><function>repeat</function>(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</literal></entry>
1653        <entry><type>text</type></entry>
1654        <entry>Repeat <parameter>string</parameter> the specified
1655        <parameter>number</parameter> of times</entry>
1656        <entry><literal>repeat('Pg', 4)</literal></entry>
1657        <entry><literal>PgPgPgPg</literal></entry>
1658       </row>
1659
1660       <row>
1661        <entry><literal><function>replace</function>(<parameter>string</parameter> <type>text</type>,
1662        <parameter>from</parameter> <type>text</type>,
1663        <parameter>to</parameter> <type>text</type>)</literal></entry>
1664        <entry><type>text</type></entry>
1665        <entry>Replace all occurrences in <parameter>string</parameter> of substring
1666         <parameter>from</parameter> with substring <parameter>to</parameter>
1667        </entry>
1668        <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
1669        <entry><literal>abXXefabXXef</literal></entry>
1670       </row>
1671
1672       <row>
1673        <entry>
1674         <literal><function>rpad</function>(<parameter>string</parameter> <type>text</type>,
1675         <parameter>length</parameter> <type>int</type>
1676         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1677        </entry>
1678        <entry><type>text</type></entry>
1679        <entry>
1680         Fill up the <parameter>string</parameter> to length
1681         <parameter>length</parameter> by appending the characters
1682         <parameter>fill</parameter> (a space by default).  If the
1683         <parameter>string</parameter> is already longer than
1684         <parameter>length</parameter> then it is truncated.
1685        </entry>
1686        <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
1687        <entry><literal>hixyx</literal></entry>
1688       </row>
1689
1690       <row>
1691        <entry><literal><function>rtrim</function>(<parameter>string</parameter> <type>text</type>
1692         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
1693        </entry>
1694        <entry><type>text</type></entry>
1695        <entry>
1696         Remove the longest string containing only characters from
1697         <parameter>characters</parameter> (a space by default) from the end of
1698         <parameter>string</parameter>
1699        </entry>
1700        <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
1701        <entry><literal>trim</literal></entry>
1702       </row>
1703
1704       <row>
1705        <entry><literal><function>split_part</function>(<parameter>string</parameter> <type>text</type>,
1706        <parameter>delimiter</parameter> <type>text</type>,
1707        <parameter>field</parameter> <type>int</type>)</literal></entry>
1708        <entry><type>text</type></entry>
1709        <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1710         and return the given field (counting from one)
1711        </entry>
1712        <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
1713        <entry><literal>def</literal></entry>
1714       </row>
1715
1716       <row>
1717        <entry><literal><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</literal></entry>
1718        <entry><type>int</type></entry>
1719        <entry>
1720         Location of specified substring (same as
1721         <literal>position(<parameter>substring</parameter> in
1722          <parameter>string</parameter>)</literal>, but note the reversed
1723         argument order)
1724        </entry>
1725        <entry><literal>strpos('high', 'ig')</literal></entry>
1726        <entry><literal>2</literal></entry>
1727       </row>
1728
1729       <row>
1730        <entry><literal><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</literal></entry>
1731        <entry><type>text</type></entry>
1732        <entry>
1733         Extract substring (same as
1734         <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
1735        </entry>
1736        <entry><literal>substr('alphabet', 3, 2)</literal></entry>
1737        <entry><literal>ph</literal></entry>
1738       </row>
1739
1740       <row>
1741        <entry><literal><function>to_ascii</function>(<parameter>string</parameter> <type>text</type>
1742         <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</literal></entry>
1743        <entry><type>text</type></entry>
1744
1745        <entry>
1746        Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
1747        (only supports conversion from  <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
1748        and <literal>WIN1250</> encodings)
1749        </entry>
1750
1751        <entry><literal>to_ascii('Karel')</literal></entry>
1752        <entry><literal>Karel</literal></entry>
1753       </row>
1754
1755       <row>
1756        <entry><literal><function>to_hex</function>(<parameter>number</parameter> <type>int</type>
1757        or <type>bigint</type>)</literal></entry>
1758        <entry><type>text</type></entry>
1759        <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
1760         representation
1761        </entry>
1762        <entry><literal>to_hex(2147483647)</literal></entry>
1763        <entry><literal>7fffffff</literal></entry>
1764       </row>
1765
1766       <row>
1767        <entry>
1768         <literal><function>translate</function>(<parameter>string</parameter> <type>text</type>,
1769         <parameter>from</parameter> <type>text</type>,
1770         <parameter>to</parameter> <type>text</type>)</literal>
1771        </entry>
1772        <entry><type>text</type></entry>
1773        <entry>
1774         Any character in <parameter>string</parameter> that matches a
1775         character in the <parameter>from</parameter> set is replaced by
1776         the corresponding character in the <parameter>to</parameter>
1777         set
1778        </entry>
1779        <entry><literal>translate('12345', '14', 'ax')</literal></entry>
1780        <entry><literal>a23x5</literal></entry>
1781       </row>       
1782       
1783      </tbody>
1784     </tgroup>
1785    </table>
1786
1787
1788    <table id="conversion-names">
1789     <title>Built-in Conversions</title>
1790     <tgroup cols="3">
1791      <thead>
1792       <row>
1793        <entry>Conversion Name
1794         <footnote>
1795          <para>
1796           The conversion names follow a standard naming scheme: The
1797           official name of the source encoding with all
1798           non-alphanumeric characters replaced by underscores followed
1799           by <literal>_to_</literal> followed by the equally processed
1800           destination encoding name. Therefore the names might deviate
1801           from the customary encoding names.
1802          </para>
1803         </footnote>
1804        </entry>
1805        <entry>Source Encoding</entry>
1806        <entry>Destination Encoding</entry>
1807       </row>
1808      </thead>
1809
1810      <tbody>
1811       <row>
1812        <entry><literal>ascii_to_mic</literal></entry>
1813        <entry><literal>SQL_ASCII</literal></entry>
1814        <entry><literal>MULE_INTERNAL</literal></entry>
1815       </row>
1816
1817       <row>
1818        <entry><literal>ascii_to_utf8</literal></entry>
1819        <entry><literal>SQL_ASCII</literal></entry>
1820        <entry><literal>UTF8</literal></entry>
1821       </row>
1822
1823       <row>
1824        <entry><literal>big5_to_euc_tw</literal></entry>
1825        <entry><literal>BIG5</literal></entry>
1826        <entry><literal>EUC_TW</literal></entry>
1827       </row>
1828
1829       <row>
1830        <entry><literal>big5_to_mic</literal></entry>
1831        <entry><literal>BIG5</literal></entry>
1832        <entry><literal>MULE_INTERNAL</literal></entry>
1833       </row>
1834
1835       <row>
1836        <entry><literal>big5_to_utf8</literal></entry>
1837        <entry><literal>BIG5</literal></entry>
1838        <entry><literal>UTF8</literal></entry>
1839       </row>
1840
1841       <row>
1842        <entry><literal>euc_cn_to_mic</literal></entry>
1843        <entry><literal>EUC_CN</literal></entry>
1844        <entry><literal>MULE_INTERNAL</literal></entry>
1845       </row>
1846
1847       <row>
1848        <entry><literal>euc_cn_to_utf8</literal></entry>
1849        <entry><literal>EUC_CN</literal></entry>
1850        <entry><literal>UTF8</literal></entry>
1851       </row>
1852
1853       <row>
1854        <entry><literal>euc_jp_to_mic</literal></entry>
1855        <entry><literal>EUC_JP</literal></entry>
1856        <entry><literal>MULE_INTERNAL</literal></entry>
1857       </row>
1858
1859       <row>
1860        <entry><literal>euc_jp_to_sjis</literal></entry>
1861        <entry><literal>EUC_JP</literal></entry>
1862        <entry><literal>SJIS</literal></entry>
1863       </row>
1864
1865       <row>
1866        <entry><literal>euc_jp_to_utf8</literal></entry>
1867        <entry><literal>EUC_JP</literal></entry>
1868        <entry><literal>UTF8</literal></entry>
1869       </row>
1870
1871       <row>
1872        <entry><literal>euc_kr_to_mic</literal></entry>
1873        <entry><literal>EUC_KR</literal></entry>
1874        <entry><literal>MULE_INTERNAL</literal></entry>
1875       </row>
1876
1877       <row>
1878        <entry><literal>euc_kr_to_utf8</literal></entry>
1879        <entry><literal>EUC_KR</literal></entry>
1880        <entry><literal>UTF8</literal></entry>
1881       </row>
1882
1883       <row>
1884        <entry><literal>euc_tw_to_big5</literal></entry>
1885        <entry><literal>EUC_TW</literal></entry>
1886        <entry><literal>BIG5</literal></entry>
1887       </row>
1888
1889       <row>
1890        <entry><literal>euc_tw_to_mic</literal></entry>
1891        <entry><literal>EUC_TW</literal></entry>
1892        <entry><literal>MULE_INTERNAL</literal></entry>
1893       </row>
1894
1895       <row>
1896        <entry><literal>euc_tw_to_utf8</literal></entry>
1897        <entry><literal>EUC_TW</literal></entry>
1898        <entry><literal>UTF8</literal></entry>
1899       </row>
1900
1901       <row>
1902        <entry><literal>gb18030_to_utf8</literal></entry>
1903        <entry><literal>GB18030</literal></entry>
1904        <entry><literal>UTF8</literal></entry>
1905       </row>
1906
1907       <row>
1908        <entry><literal>gbk_to_utf8</literal></entry>
1909        <entry><literal>GBK</literal></entry>
1910        <entry><literal>UTF8</literal></entry>
1911       </row>
1912
1913       <row>
1914        <entry><literal>iso_8859_10_to_utf8</literal></entry>
1915        <entry><literal>LATIN6</literal></entry>
1916        <entry><literal>UTF8</literal></entry>
1917       </row>
1918
1919       <row>
1920        <entry><literal>iso_8859_13_to_utf8</literal></entry>
1921        <entry><literal>LATIN7</literal></entry>
1922        <entry><literal>UTF8</literal></entry>
1923       </row>
1924
1925       <row>
1926        <entry><literal>iso_8859_14_to_utf8</literal></entry>
1927        <entry><literal>LATIN8</literal></entry>
1928        <entry><literal>UTF8</literal></entry>
1929       </row>
1930
1931       <row>
1932        <entry><literal>iso_8859_15_to_utf8</literal></entry>
1933        <entry><literal>LATIN9</literal></entry>
1934        <entry><literal>UTF8</literal></entry>
1935       </row>
1936
1937       <row>
1938        <entry><literal>iso_8859_16_to_utf8</literal></entry>
1939        <entry><literal>LATIN10</literal></entry>
1940        <entry><literal>UTF8</literal></entry>
1941       </row>
1942
1943       <row>
1944        <entry><literal>iso_8859_1_to_mic</literal></entry>
1945        <entry><literal>LATIN1</literal></entry>
1946        <entry><literal>MULE_INTERNAL</literal></entry>
1947       </row>
1948
1949       <row>
1950        <entry><literal>iso_8859_1_to_utf8</literal></entry>
1951        <entry><literal>LATIN1</literal></entry>
1952        <entry><literal>UTF8</literal></entry>
1953       </row>
1954
1955       <row>
1956        <entry><literal>iso_8859_2_to_mic</literal></entry>
1957        <entry><literal>LATIN2</literal></entry>
1958        <entry><literal>MULE_INTERNAL</literal></entry>
1959       </row>
1960
1961       <row>
1962        <entry><literal>iso_8859_2_to_utf8</literal></entry>
1963        <entry><literal>LATIN2</literal></entry>
1964        <entry><literal>UTF8</literal></entry>
1965       </row>
1966
1967       <row>
1968        <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
1969        <entry><literal>LATIN2</literal></entry>
1970        <entry><literal>WIN1250</literal></entry>
1971       </row>
1972
1973       <row>
1974        <entry><literal>iso_8859_3_to_mic</literal></entry>
1975        <entry><literal>LATIN3</literal></entry>
1976        <entry><literal>MULE_INTERNAL</literal></entry>
1977       </row>
1978
1979       <row>
1980        <entry><literal>iso_8859_3_to_utf8</literal></entry>
1981        <entry><literal>LATIN3</literal></entry>
1982        <entry><literal>UTF8</literal></entry>
1983       </row>
1984
1985       <row>
1986        <entry><literal>iso_8859_4_to_mic</literal></entry>
1987        <entry><literal>LATIN4</literal></entry>
1988        <entry><literal>MULE_INTERNAL</literal></entry>
1989       </row>
1990
1991       <row>
1992        <entry><literal>iso_8859_4_to_utf8</literal></entry>
1993        <entry><literal>LATIN4</literal></entry>
1994        <entry><literal>UTF8</literal></entry>
1995       </row>
1996
1997       <row>
1998        <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
1999        <entry><literal>ISO_8859_5</literal></entry>
2000        <entry><literal>KOI8</literal></entry>
2001       </row>
2002
2003       <row>
2004        <entry><literal>iso_8859_5_to_mic</literal></entry>
2005        <entry><literal>ISO_8859_5</literal></entry>
2006        <entry><literal>MULE_INTERNAL</literal></entry>
2007       </row>
2008
2009       <row>
2010        <entry><literal>iso_8859_5_to_utf8</literal></entry>
2011        <entry><literal>ISO_8859_5</literal></entry>
2012        <entry><literal>UTF8</literal></entry>
2013       </row>
2014
2015       <row>
2016        <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
2017        <entry><literal>ISO_8859_5</literal></entry>
2018        <entry><literal>WIN1251</literal></entry>
2019       </row>
2020
2021       <row>
2022        <entry><literal>iso_8859_5_to_windows_866</literal></entry>
2023        <entry><literal>ISO_8859_5</literal></entry>
2024        <entry><literal>WIN866</literal></entry>
2025       </row>
2026
2027       <row>
2028        <entry><literal>iso_8859_6_to_utf8</literal></entry>
2029        <entry><literal>ISO_8859_6</literal></entry>
2030        <entry><literal>UTF8</literal></entry>
2031       </row>
2032
2033       <row>
2034        <entry><literal>iso_8859_7_to_utf8</literal></entry>
2035        <entry><literal>ISO_8859_7</literal></entry>
2036        <entry><literal>UTF8</literal></entry>
2037       </row>
2038
2039       <row>
2040        <entry><literal>iso_8859_8_to_utf8</literal></entry>
2041        <entry><literal>ISO_8859_8</literal></entry>
2042        <entry><literal>UTF8</literal></entry>
2043       </row>
2044
2045       <row>
2046        <entry><literal>iso_8859_9_to_utf8</literal></entry>
2047        <entry><literal>LATIN5</literal></entry>
2048        <entry><literal>UTF8</literal></entry>
2049       </row>
2050
2051       <row>
2052        <entry><literal>johab_to_utf8</literal></entry>
2053        <entry><literal>JOHAB</literal></entry>
2054        <entry><literal>UTF8</literal></entry>
2055       </row>
2056
2057       <row>
2058        <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
2059        <entry><literal>KOI8</literal></entry>
2060        <entry><literal>ISO_8859_5</literal></entry>
2061       </row>
2062
2063       <row>
2064        <entry><literal>koi8_r_to_mic</literal></entry>
2065        <entry><literal>KOI8</literal></entry>
2066        <entry><literal>MULE_INTERNAL</literal></entry>
2067       </row>
2068
2069       <row>
2070        <entry><literal>koi8_r_to_utf8</literal></entry>
2071        <entry><literal>KOI8</literal></entry>
2072        <entry><literal>UTF8</literal></entry>
2073       </row>
2074
2075       <row>
2076        <entry><literal>koi8_r_to_windows_1251</literal></entry>
2077        <entry><literal>KOI8</literal></entry>
2078        <entry><literal>WIN1251</literal></entry>
2079       </row>
2080
2081       <row>
2082        <entry><literal>koi8_r_to_windows_866</literal></entry>
2083        <entry><literal>KOI8</literal></entry>
2084        <entry><literal>WIN866</literal></entry>
2085       </row>
2086
2087       <row>
2088        <entry><literal>mic_to_ascii</literal></entry>
2089        <entry><literal>MULE_INTERNAL</literal></entry>
2090        <entry><literal>SQL_ASCII</literal></entry>
2091       </row>
2092
2093       <row>
2094        <entry><literal>mic_to_big5</literal></entry>
2095        <entry><literal>MULE_INTERNAL</literal></entry>
2096        <entry><literal>BIG5</literal></entry>
2097       </row>
2098
2099       <row>
2100        <entry><literal>mic_to_euc_cn</literal></entry>
2101        <entry><literal>MULE_INTERNAL</literal></entry>
2102        <entry><literal>EUC_CN</literal></entry>
2103       </row>
2104
2105       <row>
2106        <entry><literal>mic_to_euc_jp</literal></entry>
2107        <entry><literal>MULE_INTERNAL</literal></entry>
2108        <entry><literal>EUC_JP</literal></entry>
2109       </row>
2110
2111       <row>
2112        <entry><literal>mic_to_euc_kr</literal></entry>
2113        <entry><literal>MULE_INTERNAL</literal></entry>
2114        <entry><literal>EUC_KR</literal></entry>
2115       </row>
2116
2117       <row>
2118        <entry><literal>mic_to_euc_tw</literal></entry>
2119        <entry><literal>MULE_INTERNAL</literal></entry>
2120        <entry><literal>EUC_TW</literal></entry>
2121       </row>
2122
2123       <row>
2124        <entry><literal>mic_to_iso_8859_1</literal></entry>
2125        <entry><literal>MULE_INTERNAL</literal></entry>
2126        <entry><literal>LATIN1</literal></entry>
2127       </row>
2128
2129       <row>
2130        <entry><literal>mic_to_iso_8859_2</literal></entry>
2131        <entry><literal>MULE_INTERNAL</literal></entry>
2132        <entry><literal>LATIN2</literal></entry>
2133       </row>
2134
2135       <row>
2136        <entry><literal>mic_to_iso_8859_3</literal></entry>
2137        <entry><literal>MULE_INTERNAL</literal></entry>
2138        <entry><literal>LATIN3</literal></entry>
2139       </row>
2140
2141       <row>
2142        <entry><literal>mic_to_iso_8859_4</literal></entry>
2143        <entry><literal>MULE_INTERNAL</literal></entry>
2144        <entry><literal>LATIN4</literal></entry>
2145       </row>
2146
2147       <row>
2148        <entry><literal>mic_to_iso_8859_5</literal></entry>
2149        <entry><literal>MULE_INTERNAL</literal></entry>
2150        <entry><literal>ISO_8859_5</literal></entry>
2151       </row>
2152
2153       <row>
2154        <entry><literal>mic_to_koi8_r</literal></entry>
2155        <entry><literal>MULE_INTERNAL</literal></entry>
2156        <entry><literal>KOI8</literal></entry>
2157       </row>
2158
2159       <row>
2160        <entry><literal>mic_to_sjis</literal></entry>
2161        <entry><literal>MULE_INTERNAL</literal></entry>
2162        <entry><literal>SJIS</literal></entry>
2163       </row>
2164
2165       <row>
2166        <entry><literal>mic_to_windows_1250</literal></entry>
2167        <entry><literal>MULE_INTERNAL</literal></entry>
2168        <entry><literal>WIN1250</literal></entry>
2169       </row>
2170
2171       <row>
2172        <entry><literal>mic_to_windows_1251</literal></entry>
2173        <entry><literal>MULE_INTERNAL</literal></entry>
2174        <entry><literal>WIN1251</literal></entry>
2175       </row>
2176
2177       <row>
2178        <entry><literal>mic_to_windows_866</literal></entry>
2179        <entry><literal>MULE_INTERNAL</literal></entry>
2180        <entry><literal>WIN866</literal></entry>
2181       </row>
2182
2183       <row>
2184        <entry><literal>sjis_to_euc_jp</literal></entry>
2185        <entry><literal>SJIS</literal></entry>
2186        <entry><literal>EUC_JP</literal></entry>
2187       </row>
2188
2189       <row>
2190        <entry><literal>sjis_to_mic</literal></entry>
2191        <entry><literal>SJIS</literal></entry>
2192        <entry><literal>MULE_INTERNAL</literal></entry>
2193       </row>
2194
2195       <row>
2196        <entry><literal>sjis_to_utf8</literal></entry>
2197        <entry><literal>SJIS</literal></entry>
2198        <entry><literal>UTF8</literal></entry>
2199       </row>
2200
2201       <row>
2202        <entry><literal>tcvn_to_utf8</literal></entry>
2203        <entry><literal>WIN1258</literal></entry>
2204        <entry><literal>UTF8</literal></entry>
2205       </row>
2206
2207       <row>
2208        <entry><literal>uhc_to_utf8</literal></entry>
2209        <entry><literal>UHC</literal></entry>
2210        <entry><literal>UTF8</literal></entry>
2211       </row>
2212
2213       <row>
2214        <entry><literal>utf8_to_ascii</literal></entry>
2215        <entry><literal>UTF8</literal></entry>
2216        <entry><literal>SQL_ASCII</literal></entry>
2217       </row>
2218
2219       <row>
2220        <entry><literal>utf8_to_big5</literal></entry>
2221        <entry><literal>UTF8</literal></entry>
2222        <entry><literal>BIG5</literal></entry>
2223       </row>
2224
2225       <row>
2226        <entry><literal>utf8_to_euc_cn</literal></entry>
2227        <entry><literal>UTF8</literal></entry>
2228        <entry><literal>EUC_CN</literal></entry>
2229       </row>
2230
2231       <row>
2232        <entry><literal>utf8_to_euc_jp</literal></entry>
2233        <entry><literal>UTF8</literal></entry>
2234        <entry><literal>EUC_JP</literal></entry>
2235       </row>
2236
2237       <row>
2238        <entry><literal>utf8_to_euc_kr</literal></entry>
2239        <entry><literal>UTF8</literal></entry>
2240        <entry><literal>EUC_KR</literal></entry>
2241       </row>
2242
2243       <row>
2244        <entry><literal>utf8_to_euc_tw</literal></entry>
2245        <entry><literal>UTF8</literal></entry>
2246        <entry><literal>EUC_TW</literal></entry>
2247       </row>
2248
2249       <row>
2250        <entry><literal>utf8_to_gb18030</literal></entry>
2251        <entry><literal>UTF8</literal></entry>
2252        <entry><literal>GB18030</literal></entry>
2253       </row>
2254
2255       <row>
2256        <entry><literal>utf8_to_gbk</literal></entry>
2257        <entry><literal>UTF8</literal></entry>
2258        <entry><literal>GBK</literal></entry>
2259       </row>
2260
2261       <row>
2262        <entry><literal>utf8_to_iso_8859_1</literal></entry>
2263        <entry><literal>UTF8</literal></entry>
2264        <entry><literal>LATIN1</literal></entry>
2265       </row>
2266
2267       <row>
2268        <entry><literal>utf8_to_iso_8859_10</literal></entry>
2269        <entry><literal>UTF8</literal></entry>
2270        <entry><literal>LATIN6</literal></entry>
2271       </row>
2272
2273       <row>
2274        <entry><literal>utf8_to_iso_8859_13</literal></entry>
2275        <entry><literal>UTF8</literal></entry>
2276        <entry><literal>LATIN7</literal></entry>
2277       </row>
2278
2279       <row>
2280        <entry><literal>utf8_to_iso_8859_14</literal></entry>
2281        <entry><literal>UTF8</literal></entry>
2282        <entry><literal>LATIN8</literal></entry>
2283       </row>
2284
2285       <row>
2286        <entry><literal>utf8_to_iso_8859_15</literal></entry>
2287        <entry><literal>UTF8</literal></entry>
2288        <entry><literal>LATIN9</literal></entry>
2289       </row>
2290
2291       <row>
2292        <entry><literal>utf8_to_iso_8859_16</literal></entry>
2293        <entry><literal>UTF8</literal></entry>
2294        <entry><literal>LATIN10</literal></entry>
2295       </row>
2296
2297       <row>
2298        <entry><literal>utf8_to_iso_8859_2</literal></entry>
2299        <entry><literal>UTF8</literal></entry>
2300        <entry><literal>LATIN2</literal></entry>
2301       </row>
2302
2303       <row>
2304        <entry><literal>utf8_to_iso_8859_3</literal></entry>
2305        <entry><literal>UTF8</literal></entry>
2306        <entry><literal>LATIN3</literal></entry>
2307       </row>
2308
2309       <row>
2310        <entry><literal>utf8_to_iso_8859_4</literal></entry>
2311        <entry><literal>UTF8</literal></entry>
2312        <entry><literal>LATIN4</literal></entry>
2313       </row>
2314
2315       <row>
2316        <entry><literal>utf8_to_iso_8859_5</literal></entry>
2317        <entry><literal>UTF8</literal></entry>
2318        <entry><literal>ISO_8859_5</literal></entry>
2319       </row>
2320
2321       <row>
2322        <entry><literal>utf8_to_iso_8859_6</literal></entry>
2323        <entry><literal>UTF8</literal></entry>
2324        <entry><literal>ISO_8859_6</literal></entry>
2325       </row>
2326
2327       <row>
2328        <entry><literal>utf8_to_iso_8859_7</literal></entry>
2329        <entry><literal>UTF8</literal></entry>
2330        <entry><literal>ISO_8859_7</literal></entry>
2331       </row>
2332
2333       <row>
2334        <entry><literal>utf8_to_iso_8859_8</literal></entry>
2335        <entry><literal>UTF8</literal></entry>
2336        <entry><literal>ISO_8859_8</literal></entry>
2337       </row>
2338
2339       <row>
2340        <entry><literal>utf8_to_iso_8859_9</literal></entry>
2341        <entry><literal>UTF8</literal></entry>
2342        <entry><literal>LATIN5</literal></entry>
2343       </row>
2344
2345       <row>
2346        <entry><literal>utf8_to_johab</literal></entry>
2347        <entry><literal>UTF8</literal></entry>
2348        <entry><literal>JOHAB</literal></entry>
2349       </row>
2350
2351       <row>
2352        <entry><literal>utf8_to_koi8_r</literal></entry>
2353        <entry><literal>UTF8</literal></entry>
2354        <entry><literal>KOI8</literal></entry>
2355       </row>
2356
2357       <row>
2358        <entry><literal>utf8_to_sjis</literal></entry>
2359        <entry><literal>UTF8</literal></entry>
2360        <entry><literal>SJIS</literal></entry>
2361       </row>
2362
2363       <row>
2364        <entry><literal>utf8_to_tcvn</literal></entry>
2365        <entry><literal>UTF8</literal></entry>
2366        <entry><literal>WIN1258</literal></entry>
2367       </row>
2368
2369       <row>
2370        <entry><literal>utf8_to_uhc</literal></entry>
2371        <entry><literal>UTF8</literal></entry>
2372        <entry><literal>UHC</literal></entry>
2373       </row>
2374
2375       <row>
2376        <entry><literal>utf8_to_windows_1250</literal></entry>
2377        <entry><literal>UTF8</literal></entry>
2378        <entry><literal>WIN1250</literal></entry>
2379       </row>
2380
2381       <row>
2382        <entry><literal>utf8_to_windows_1251</literal></entry>
2383        <entry><literal>UTF8</literal></entry>
2384        <entry><literal>WIN1251</literal></entry>
2385       </row>
2386
2387       <row>
2388        <entry><literal>utf8_to_windows_1252</literal></entry>
2389        <entry><literal>UTF8</literal></entry>
2390        <entry><literal>WIN1252</literal></entry>
2391       </row>
2392
2393       <row>
2394        <entry><literal>utf8_to_windows_1253</literal></entry>
2395        <entry><literal>UTF8</literal></entry>
2396        <entry><literal>WIN1253</literal></entry>
2397       </row>
2398
2399       <row>
2400        <entry><literal>utf8_to_windows_1254</literal></entry>
2401        <entry><literal>UTF8</literal></entry>
2402        <entry><literal>WIN1254</literal></entry>
2403       </row>
2404
2405       <row>
2406        <entry><literal>utf8_to_windows_1255</literal></entry>
2407        <entry><literal>UTF8</literal></entry>
2408        <entry><literal>WIN1255</literal></entry>
2409       </row>
2410
2411       <row>
2412        <entry><literal>utf8_to_windows_1256</literal></entry>
2413        <entry><literal>UTF8</literal></entry>
2414        <entry><literal>WIN1256</literal></entry>
2415       </row>
2416
2417       <row>
2418        <entry><literal>utf8_to_windows_1257</literal></entry>
2419        <entry><literal>UTF8</literal></entry>
2420        <entry><literal>WIN1257</literal></entry>
2421       </row>
2422
2423       <row>
2424        <entry><literal>utf8_to_windows_866</literal></entry>
2425        <entry><literal>UTF8</literal></entry>
2426        <entry><literal>WIN866</literal></entry>
2427       </row>
2428
2429       <row>
2430        <entry><literal>utf8_to_windows_874</literal></entry>
2431        <entry><literal>UTF8</literal></entry>
2432        <entry><literal>WIN874</literal></entry>
2433       </row>
2434
2435       <row>
2436        <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
2437        <entry><literal>WIN1250</literal></entry>
2438        <entry><literal>LATIN2</literal></entry>
2439       </row>
2440
2441       <row>
2442        <entry><literal>windows_1250_to_mic</literal></entry>
2443        <entry><literal>WIN1250</literal></entry>
2444        <entry><literal>MULE_INTERNAL</literal></entry>
2445       </row>
2446
2447       <row>
2448        <entry><literal>windows_1250_to_utf8</literal></entry>
2449        <entry><literal>WIN1250</literal></entry>
2450        <entry><literal>UTF8</literal></entry>
2451       </row>
2452
2453       <row>
2454        <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
2455        <entry><literal>WIN1251</literal></entry>
2456        <entry><literal>ISO_8859_5</literal></entry>
2457       </row>
2458
2459       <row>
2460        <entry><literal>windows_1251_to_koi8_r</literal></entry>
2461        <entry><literal>WIN1251</literal></entry>
2462        <entry><literal>KOI8</literal></entry>
2463       </row>
2464
2465       <row>
2466        <entry><literal>windows_1251_to_mic</literal></entry>
2467        <entry><literal>WIN1251</literal></entry>
2468        <entry><literal>MULE_INTERNAL</literal></entry>
2469       </row>
2470
2471       <row>
2472        <entry><literal>windows_1251_to_utf8</literal></entry>
2473        <entry><literal>WIN1251</literal></entry>
2474        <entry><literal>UTF8</literal></entry>
2475       </row>
2476
2477       <row>
2478        <entry><literal>windows_1251_to_windows_866</literal></entry>
2479        <entry><literal>WIN1251</literal></entry>
2480        <entry><literal>WIN866</literal></entry>
2481       </row>
2482
2483       <row>
2484        <entry><literal>windows_1252_to_utf8</literal></entry>
2485        <entry><literal>WIN1252</literal></entry>
2486        <entry><literal>UTF8</literal></entry>
2487       </row>
2488
2489       <row>
2490        <entry><literal>windows_1256_to_utf8</literal></entry>
2491        <entry><literal>WIN1256</literal></entry>
2492        <entry><literal>UTF8</literal></entry>
2493       </row>
2494
2495       <row>
2496        <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2497        <entry><literal>WIN866</literal></entry>
2498        <entry><literal>ISO_8859_5</literal></entry>
2499       </row>
2500
2501       <row>
2502        <entry><literal>windows_866_to_koi8_r</literal></entry>
2503        <entry><literal>WIN866</literal></entry>
2504        <entry><literal>KOI8</literal></entry>
2505       </row>
2506
2507       <row>
2508        <entry><literal>windows_866_to_mic</literal></entry>
2509        <entry><literal>WIN866</literal></entry>
2510        <entry><literal>MULE_INTERNAL</literal></entry>
2511       </row>
2512
2513       <row>
2514        <entry><literal>windows_866_to_utf8</literal></entry>
2515        <entry><literal>WIN866</literal></entry>
2516        <entry><literal>UTF8</literal></entry>
2517       </row>
2518
2519       <row>
2520        <entry><literal>windows_866_to_windows_1251</literal></entry>
2521        <entry><literal>WIN866</literal></entry>
2522        <entry><literal>WIN</literal></entry>
2523       </row>
2524
2525       <row>
2526        <entry><literal>windows_874_to_utf8</literal></entry>
2527        <entry><literal>WIN874</literal></entry>
2528        <entry><literal>UTF8</literal></entry>
2529       </row>
2530
2531       <row>
2532        <entry><literal>euc_jis_2004_to_utf8</literal></entry>
2533        <entry><literal>EUC_JIS_2004</literal></entry>
2534        <entry><literal>UTF8</literal></entry>
2535       </row>
2536
2537       <row>
2538        <entry><literal>ut8_to_euc_jis_2004</literal></entry>
2539        <entry><literal>UTF8</literal></entry>
2540        <entry><literal>EUC_JIS_2004</literal></entry>
2541       </row>
2542
2543       <row>
2544        <entry><literal>shift_jis_2004_to_utf8</literal></entry>
2545        <entry><literal>SHIFT_JIS_2004</literal></entry>
2546        <entry><literal>UTF8</literal></entry>
2547       </row>
2548
2549       <row>
2550        <entry><literal>ut8_to_shift_jis_2004</literal></entry>
2551        <entry><literal>UTF8</literal></entry>
2552        <entry><literal>SHIFT_JIS_2004</literal></entry>
2553       </row>
2554
2555       <row>
2556        <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
2557        <entry><literal>EUC_JIS_2004</literal></entry>
2558        <entry><literal>SHIFT_JIS_2004</literal></entry>
2559       </row>
2560
2561       <row>
2562        <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
2563        <entry><literal>SHIFT_JIS_2004</literal></entry>
2564        <entry><literal>EUC_JIS_2004</literal></entry>
2565       </row>
2566
2567      </tbody>
2568     </tgroup>
2569    </table>
2570
2571   </sect1>
2572
2573
2574   <sect1 id="functions-binarystring">
2575    <title>Binary String Functions and Operators</title>
2576
2577    <indexterm zone="functions-binarystring">
2578     <primary>binary data</primary>
2579     <secondary>functions</secondary>
2580    </indexterm>
2581
2582    <para>
2583     This section describes functions and operators for examining and
2584     manipulating values of type <type>bytea</type>.
2585    </para>
2586
2587    <para>
2588     <acronym>SQL</acronym> defines some string functions with a
2589     special syntax where 
2590     certain key words rather than commas are used to separate the
2591     arguments.  Details are in
2592     <xref linkend="functions-binarystring-sql">.
2593     Some functions are also implemented using the regular syntax for
2594     function invocation.
2595     (See <xref linkend="functions-binarystring-other">.)
2596    </para>
2597
2598    <table id="functions-binarystring-sql">
2599     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
2600     <tgroup cols="5">
2601      <thead>
2602       <row>
2603        <entry>Function</entry>
2604        <entry>Return Type</entry>
2605        <entry>Description</entry>
2606        <entry>Example</entry>
2607        <entry>Result</entry>  
2608       </row>
2609      </thead>
2610
2611      <tbody>
2612       <row>
2613        <entry><literal><parameter>string</parameter> <literal>||</literal>
2614         <parameter>string</parameter></literal></entry>
2615        <entry> <type>bytea</type> </entry>
2616        <entry>
2617         String concatenation
2618         <indexterm>
2619          <primary>binary string</primary>
2620          <secondary>concatenation</secondary>
2621         </indexterm>
2622        </entry>
2623        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
2624        <entry><literal>\\Post'gres\000</literal></entry>
2625       </row>
2626
2627       <row>
2628        <entry><function>get_bit</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2629        <entry><type>int</type></entry>
2630        <entry>
2631         Extract bit from string
2632         <indexterm>
2633          <primary>get_bit</primary>
2634         </indexterm>
2635        </entry>
2636        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
2637        <entry><literal>1</literal></entry>
2638       </row>
2639
2640       <row>
2641        <entry><function>get_byte</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2642        <entry><type>int</type></entry>
2643        <entry>
2644         Extract byte from string
2645         <indexterm>
2646          <primary>get_byte</primary>
2647         </indexterm>
2648        </entry>
2649        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
2650        <entry><literal>109</literal></entry>
2651       </row>
2652
2653       <row>
2654        <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
2655        <entry><type>int</type></entry>
2656        <entry>Number of bytes in binary string</entry>
2657        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
2658        <entry><literal>5</literal></entry>
2659       </row>
2660
2661       <row>
2662        <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
2663        <entry><type>int</type></entry>
2664        <entry>Location of specified substring</entry>
2665       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
2666        <entry><literal>3</literal></entry>
2667       </row>
2668
2669       <row>
2670        <entry><function>set_bit</function>(<parameter>string</parameter>,
2671        <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2672        <entry><type>bytea</type></entry>
2673        <entry>
2674         Set bit in string
2675         <indexterm>
2676          <primary>set_bit</primary>
2677         </indexterm>
2678        </entry>
2679        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
2680        <entry><literal>Th\000omAs</literal></entry>
2681       </row>
2682
2683       <row>
2684        <entry><function>set_byte</function>(<parameter>string</parameter>,
2685        <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2686        <entry><type>bytea</type></entry>
2687        <entry>
2688         Set byte in string
2689         <indexterm>
2690          <primary>set_byte</primary>
2691         </indexterm>
2692        </entry>
2693        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
2694        <entry><literal>Th\000o@as</literal></entry>
2695       </row>
2696
2697       <row>
2698        <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
2699        <entry><type>bytea</type></entry>
2700        <entry>
2701         Extract substring
2702         <indexterm>
2703          <primary>substring</primary>
2704         </indexterm>
2705        </entry>
2706        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
2707        <entry><literal>h\000o</literal></entry>
2708       </row>
2709
2710       <row>
2711        <entry>
2712         <literal><function>trim</function>(<optional>both</optional>
2713         <parameter>bytes</parameter> from
2714         <parameter>string</parameter>)</literal>
2715        </entry>
2716        <entry><type>bytea</type></entry>
2717        <entry>
2718         Remove the longest string containing only the bytes in
2719         <parameter>bytes</parameter> from the start
2720         and end of <parameter>string</parameter>
2721        </entry>
2722        <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
2723        <entry><literal>Tom</literal></entry>
2724       </row>
2725      </tbody>
2726     </tgroup>
2727    </table>
2728
2729    <para>
2730     Additional binary string manipulation functions are available and
2731     are listed in <xref linkend="functions-binarystring-other">.  Some
2732     of them are used internally to implement the
2733     <acronym>SQL</acronym>-standard string functions listed in <xref
2734     linkend="functions-binarystring-sql">.
2735    </para>
2736
2737    <table id="functions-binarystring-other">
2738     <title>Other Binary String Functions</title>
2739     <tgroup cols="5">
2740      <thead>
2741       <row>
2742        <entry>Function</entry>
2743        <entry>Return Type</entry>
2744        <entry>Description</entry>
2745        <entry>Example</entry>
2746        <entry>Result</entry>
2747       </row>
2748      </thead>
2749
2750      <tbody>
2751       <row>
2752        <entry><literal><function>btrim</function>(<parameter>string</parameter>
2753         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</literal></entry>
2754        <entry><type>bytea</type></entry>
2755        <entry>
2756         Remove the longest string consisting only of bytes
2757         in <parameter>bytes</parameter> from the start and end of
2758         <parameter>string</parameter>
2759       </entry>
2760       <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
2761       <entry><literal>trim</literal></entry>
2762      </row>
2763
2764      <row>
2765       <entry>
2766        <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
2767               <parameter>type</parameter> <type>text</type>)</literal>
2768       </entry>
2769       <entry><type>bytea</type></entry>
2770       <entry>
2771        Decode binary string from <parameter>string</parameter> previously 
2772        encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
2773       </entry>
2774       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
2775       <entry><literal>123\000456</literal></entry>
2776      </row>
2777
2778      <row>
2779       <entry>
2780        <literal><function>encode</function>(<parameter>string</parameter> <type>bytea</type>,
2781               <parameter>type</parameter> <type>text</type>)</literal>
2782       </entry>
2783       <entry><type>text</type></entry>
2784       <entry>
2785        Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
2786        types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
2787       </entry>
2788       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
2789       <entry><literal>123\000456</literal></entry>
2790      </row>
2791
2792      <row>
2793       <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
2794       <entry><type>int</type></entry>
2795       <entry>
2796        Length of binary string
2797        <indexterm>
2798         <primary>binary string</primary>
2799         <secondary>length</secondary>
2800        </indexterm>
2801        <indexterm>
2802         <primary>length</primary>
2803         <secondary sortas="binary string">of a binary string</secondary>
2804         <see>binary strings, length</see>
2805        </indexterm>
2806       </entry>
2807       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
2808       <entry><literal>5</literal></entry>
2809      </row>
2810
2811      <row>
2812       <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
2813       <entry><type>text</type></entry>
2814       <entry>
2815        Calculates the MD5 hash of <parameter>string</parameter>,
2816        returning the result in hexadecimal
2817       </entry>
2818       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
2819       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
2820      </row>
2821     </tbody>
2822    </tgroup>
2823   </table>
2824
2825  </sect1>
2826
2827
2828   <sect1 id="functions-bitstring">
2829    <title>Bit String Functions and Operators</title>
2830
2831    <indexterm zone="functions-bitstring">
2832     <primary>bit strings</primary>
2833     <secondary>functions</secondary>
2834    </indexterm>
2835
2836    <para>
2837     This section describes functions and operators for examining and
2838     manipulating bit strings, that is values of the types
2839     <type>bit</type> and <type>bit varying</type>.  Aside from the
2840     usual comparison operators, the operators
2841     shown in <xref linkend="functions-bit-string-op-table"> can be used.
2842     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
2843     and <literal>#</literal> must be of equal length.  When bit
2844     shifting, the original length of the string is preserved, as shown
2845     in the examples.
2846    </para>
2847
2848    <table id="functions-bit-string-op-table">
2849     <title>Bit String Operators</title>
2850
2851     <tgroup cols="4">
2852      <thead>
2853       <row>
2854        <entry>Operator</entry>
2855        <entry>Description</entry>
2856        <entry>Example</entry>
2857        <entry>Result</entry>
2858       </row>
2859      </thead>
2860
2861      <tbody>
2862       <row>
2863        <entry> <literal>||</literal> </entry>
2864        <entry>concatenation</entry>
2865        <entry><literal>B'10001' || B'011'</literal></entry>
2866        <entry><literal>10001011</literal></entry>
2867       </row>
2868
2869       <row>
2870        <entry> <literal>&amp;</literal> </entry>
2871        <entry>bitwise AND</entry>
2872        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
2873        <entry><literal>00001</literal></entry>
2874       </row>
2875
2876       <row>
2877        <entry> <literal>|</literal> </entry>
2878        <entry>bitwise OR</entry>
2879        <entry><literal>B'10001' | B'01101'</literal></entry>
2880        <entry><literal>11101</literal></entry>
2881       </row>
2882
2883       <row>
2884        <entry> <literal>#</literal> </entry>
2885        <entry>bitwise XOR</entry>
2886        <entry><literal>B'10001' # B'01101'</literal></entry>
2887        <entry><literal>11100</literal></entry>
2888       </row>
2889
2890       <row>
2891        <entry> <literal>~</literal> </entry>
2892        <entry>bitwise NOT</entry>
2893        <entry><literal>~ B'10001'</literal></entry>
2894        <entry><literal>01110</literal></entry>
2895       </row>
2896
2897       <row>
2898        <entry> <literal>&lt;&lt;</literal> </entry>
2899        <entry>bitwise shift left</entry>
2900        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
2901        <entry><literal>01000</literal></entry>
2902       </row>
2903
2904       <row>
2905        <entry> <literal>&gt;&gt;</literal> </entry>
2906        <entry>bitwise shift right</entry>
2907        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
2908        <entry><literal>00100</literal></entry>
2909       </row>
2910      </tbody>
2911     </tgroup>
2912    </table>
2913
2914    <para>
2915     The following <acronym>SQL</acronym>-standard functions work on bit
2916     strings as well as character strings:
2917     <literal><function>length</function></literal>,
2918     <literal><function>bit_length</function></literal>,
2919     <literal><function>octet_length</function></literal>,
2920     <literal><function>position</function></literal>,
2921     <literal><function>substring</function></literal>.
2922    </para>
2923
2924    <para>
2925     In addition, it is possible to cast integral values to and from type
2926     <type>bit</>.
2927     Some examples:
2928 <programlisting>
2929 44::bit(10)                    <lineannotation>0000101100</lineannotation>
2930 44::bit(3)                     <lineannotation>100</lineannotation>
2931 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
2932 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
2933 </programlisting>
2934     Note that casting to just <quote>bit</> means casting to
2935     <literal>bit(1)</>, and so it will deliver only the least significant
2936     bit of the integer.
2937    </para>
2938
2939     <note>
2940      <para>
2941       Prior to <productname>PostgreSQL</productname> 8.0, casting an
2942       integer to <type>bit(n)</> would copy the leftmost <literal>n</>
2943       bits of the integer, whereas now it copies the rightmost <literal>n</>
2944       bits.  Also, casting an integer to a bit string width wider than
2945       the integer itself will sign-extend on the left.
2946      </para>
2947     </note>
2948
2949   </sect1>
2950
2951
2952  <sect1 id="functions-matching">
2953   <title>Pattern Matching</title>
2954
2955   <indexterm zone="functions-matching">
2956    <primary>pattern matching</primary>
2957   </indexterm>
2958
2959    <para>
2960     There are three separate approaches to pattern matching provided
2961     by <productname>PostgreSQL</productname>: the traditional
2962     <acronym>SQL</acronym> <function>LIKE</function> operator, the
2963     more recent <function>SIMILAR TO</function> operator (added in
2964     SQL:1999), and <acronym>POSIX</acronym>-style regular
2965     expressions.  Aside from the basic <quote>does this string match
2966     this pattern?</> operators, functions are available to extract
2967     or replace matching substrings and to split a string at the matches.
2968    </para>
2969
2970    <tip>
2971     <para>
2972      If you have pattern matching needs that go beyond this,
2973      consider writing a user-defined function in Perl or Tcl.
2974     </para>
2975    </tip>
2976
2977   <sect2 id="functions-like">
2978    <title><function>LIKE</function></title>
2979
2980    <indexterm>
2981     <primary>LIKE</primary>
2982    </indexterm>
2983
2984 <synopsis>
2985 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
2986 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
2987 </synopsis>
2988
2989     <para>
2990      Every <replaceable>pattern</replaceable> defines a set of strings.
2991      The <function>LIKE</function> expression returns true if the
2992      <replaceable>string</replaceable> is contained in the set of
2993      strings represented by <replaceable>pattern</replaceable>.  (As
2994      expected, the <function>NOT LIKE</function> expression returns
2995      false if <function>LIKE</function> returns true, and vice versa.
2996      An equivalent expression is
2997      <literal>NOT (<replaceable>string</replaceable> LIKE
2998       <replaceable>pattern</replaceable>)</literal>.)
2999     </para>
3000
3001     <para>
3002      If <replaceable>pattern</replaceable> does not contain percent
3003      signs or underscore, then the pattern only represents the string
3004      itself; in that case <function>LIKE</function> acts like the
3005      equals operator.  An underscore (<literal>_</literal>) in
3006      <replaceable>pattern</replaceable> stands for (matches) any single
3007      character; a percent sign (<literal>%</literal>) matches any string
3008      of zero or more characters.
3009     </para>
3010
3011    <para>
3012     Some examples:
3013 <programlisting>
3014 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
3015 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
3016 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
3017 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
3018 </programlisting>
3019    </para>
3020    
3021    <para>
3022     <function>LIKE</function> pattern matches always cover the entire
3023     string.  To match a sequence anywhere within a string, the
3024     pattern must therefore start and end with a percent sign.
3025    </para>
3026
3027    <para>
3028     To match a literal underscore or percent sign without matching
3029     other characters, the respective character in
3030     <replaceable>pattern</replaceable> must be 
3031     preceded by the escape character.  The default escape
3032     character is the backslash but a different one can be selected by
3033     using the <literal>ESCAPE</literal> clause.  To match the escape
3034     character itself, write two escape characters.
3035    </para>
3036
3037    <para>
3038     Note that the backslash already has a special meaning in string literals,
3039     so to write a pattern constant that contains a backslash you must write two
3040     backslashes in an SQL statement (assuming escape string syntax is used, see
3041     <xref linkend="sql-syntax-strings">).  Thus, writing a pattern that
3042     actually matches a literal backslash means writing four backslashes in the
3043     statement.  You can avoid this by selecting a different escape character
3044     with <literal>ESCAPE</literal>; then a backslash is not special to
3045     <function>LIKE</function> anymore. (But it is still special to the string
3046     literal parser, so you still need two of them.)
3047    </para>
3048
3049    <para>
3050     It's also possible to select no escape character by writing
3051     <literal>ESCAPE ''</literal>.  This effectively disables the
3052     escape mechanism, which makes it impossible to turn off the
3053     special meaning of underscore and percent signs in the pattern.
3054    </para>
3055
3056    <para>
3057     The key word <token>ILIKE</token> can be used instead of
3058     <token>LIKE</token> to make the match case-insensitive according
3059     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3060     <productname>PostgreSQL</productname> extension.
3061    </para>
3062
3063    <para>
3064     The operator <literal>~~</literal> is equivalent to
3065     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3066     <function>ILIKE</function>.  There are also
3067     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3068     represent <function>NOT LIKE</function> and <function>NOT
3069     ILIKE</function>, respectively.  All of these operators are
3070     <productname>PostgreSQL</productname>-specific.
3071    </para>
3072   </sect2>
3073
3074
3075   <sect2 id="functions-similarto-regexp">
3076    <title><function>SIMILAR TO</function> Regular Expressions</title>
3077
3078    <indexterm>
3079     <primary>regular expression</primary>
3080     <!-- <seealso>pattern matching</seealso> breaks index build -->
3081    </indexterm>
3082
3083    <indexterm>
3084     <primary>SIMILAR TO</primary>
3085    </indexterm>
3086    <indexterm>
3087     <primary>substring</primary>
3088    </indexterm>
3089
3090 <synopsis>
3091 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3092 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3093 </synopsis>
3094
3095    <para>
3096     The <function>SIMILAR TO</function> operator returns true or
3097     false depending on whether its pattern matches the given string.
3098     It is much like <function>LIKE</function>, except that it
3099     interprets the pattern using the SQL standard's definition of a
3100     regular expression.  SQL regular expressions are a curious cross
3101     between <function>LIKE</function> notation and common regular
3102     expression notation.
3103    </para>
3104
3105    <para>
3106     Like <function>LIKE</function>, the  <function>SIMILAR TO</function>
3107     operator succeeds only if its pattern matches the entire string;
3108     this is unlike common regular expression practice, wherein the pattern
3109     can match any part of the string.
3110     Also like
3111     <function>LIKE</function>, <function>SIMILAR TO</function> uses
3112     <literal>_</> and <literal>%</> as wildcard characters denoting
3113     any single character and any string, respectively (these are
3114     comparable to <literal>.</> and <literal>.*</> in POSIX regular
3115     expressions).
3116    </para>
3117
3118    <para>
3119     In addition to these facilities borrowed from <function>LIKE</function>,
3120     <function>SIMILAR TO</function> supports these pattern-matching
3121     metacharacters borrowed from POSIX regular expressions:
3122
3123    <itemizedlist>
3124     <listitem>
3125      <para>
3126       <literal>|</literal> denotes alternation (either of two alternatives).
3127      </para>
3128     </listitem>
3129     <listitem>
3130      <para>
3131       <literal>*</literal> denotes repetition of the previous item zero
3132       or more times.
3133      </para>
3134     </listitem>
3135     <listitem>
3136      <para>
3137       <literal>+</literal> denotes repetition of the previous item one
3138       or more times.
3139      </para>
3140     </listitem>
3141     <listitem>
3142      <para>
3143       Parentheses <literal>()</literal> can be used to group items into
3144       a single logical item.
3145      </para>
3146     </listitem>
3147     <listitem>
3148      <para>
3149       A bracket expression <literal>[...]</literal> specifies a character
3150       class, just as in POSIX regular expressions.
3151      </para>
3152     </listitem>
3153    </itemizedlist>
3154
3155     Notice that bounded repetition (<literal>?</> and <literal>{...}</>)
3156     are not provided, though they exist in POSIX.  Also, the dot (<literal>.</>)
3157     is not a metacharacter.
3158    </para>
3159
3160    <para>
3161     As with <function>LIKE</>, a backslash disables the special meaning
3162     of any of these metacharacters; or a different escape character can
3163     be specified with <literal>ESCAPE</>.
3164    </para>
3165
3166    <para>
3167     Some examples:
3168 <programlisting>
3169 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
3170 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
3171 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
3172 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
3173 </programlisting>
3174    </para>
3175
3176    <para>
3177     The <function>substring</> function with three parameters,
3178     <function>substring(<replaceable>string</replaceable> from
3179     <replaceable>pattern</replaceable> for
3180     <replaceable>escape-character</replaceable>)</function>, provides
3181     extraction of a substring that matches an SQL
3182     regular expression pattern.  As with <literal>SIMILAR TO</>, the
3183     specified pattern must match to the entire data string, else the
3184     function fails and returns null.  To indicate the part of the
3185     pattern that should be returned on success, the pattern must contain
3186     two occurrences of the escape character followed by a double quote
3187     (<literal>"</>). <!-- " font-lock sanity -->
3188     The text matching the portion of the pattern
3189     between these markers is returned.
3190    </para>
3191
3192    <para>
3193     Some examples:
3194 <programlisting>
3195 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
3196 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
3197 </programlisting>
3198    </para>
3199   </sect2>
3200
3201   <sect2 id="functions-posix-regexp">
3202    <title><acronym>POSIX</acronym> Regular Expressions</title>
3203
3204    <indexterm zone="functions-posix-regexp">
3205     <primary>regular expression</primary>
3206     <seealso>pattern matching</seealso>
3207    </indexterm>
3208    <indexterm>
3209     <primary>substring</primary>
3210    </indexterm>
3211    <indexterm>
3212     <primary>regexp_replace</primary>
3213    </indexterm>
3214    <indexterm>
3215     <primary>regexp_matches</primary>
3216    </indexterm>
3217    <indexterm>
3218     <primary>regexp_split_to_table</primary>
3219    </indexterm>
3220    <indexterm>
3221     <primary>regexp_split_to_array</primary>
3222    </indexterm>
3223
3224    <para>
3225     <xref linkend="functions-posix-table"> lists the available
3226     operators for pattern matching using POSIX regular expressions.
3227    </para>
3228
3229    <table id="functions-posix-table">
3230     <title>Regular Expression Match Operators</title>
3231
3232     <tgroup cols="3">
3233      <thead>
3234       <row>
3235        <entry>Operator</entry>
3236        <entry>Description</entry>
3237        <entry>Example</entry>
3238       </row>
3239      </thead>
3240
3241       <tbody>
3242        <row>
3243         <entry> <literal>~</literal> </entry>
3244         <entry>Matches regular expression, case sensitive</entry>
3245         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3246        </row>
3247
3248        <row>
3249         <entry> <literal>~*</literal> </entry>
3250         <entry>Matches regular expression, case insensitive</entry>
3251         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3252        </row>
3253
3254        <row>
3255         <entry> <literal>!~</literal> </entry>
3256         <entry>Does not match regular expression, case sensitive</entry>
3257         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3258        </row>
3259
3260        <row>
3261         <entry> <literal>!~*</literal> </entry>
3262         <entry>Does not match regular expression, case insensitive</entry>
3263         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3264        </row>
3265       </tbody>
3266      </tgroup>
3267     </table>
3268
3269     <para>
3270      <acronym>POSIX</acronym> regular expressions provide a more
3271      powerful means for 
3272      pattern matching than the <function>LIKE</function> and
3273      <function>SIMILAR TO</> operators.
3274      Many Unix tools such as <command>egrep</command>,
3275      <command>sed</command>, or <command>awk</command> use a pattern
3276      matching language that is similar to the one described here.
3277     </para>
3278
3279     <para>
3280      A regular expression is a character sequence that is an
3281      abbreviated definition of a set of strings (a <firstterm>regular
3282      set</firstterm>).  A string is said to match a regular expression
3283      if it is a member of the regular set described by the regular
3284      expression.  As with <function>LIKE</function>, pattern characters
3285      match string characters exactly unless they are special characters
3286      in the regular expression language &mdash; but regular expressions use
3287      different special characters than <function>LIKE</function> does.
3288      Unlike <function>LIKE</function> patterns, a
3289      regular expression is allowed to match anywhere within a string, unless
3290      the regular expression is explicitly anchored to the beginning or
3291      end of the string.
3292     </para>
3293
3294     <para>
3295      Some examples:
3296 <programlisting>
3297 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
3298 'abc' ~ '^a'     <lineannotation>true</lineannotation>
3299 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
3300 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3301 </programlisting>
3302     </para>
3303
3304     <para>
3305      The <acronym>POSIX</acronym> pattern language is described in much
3306      greater detail below.
3307     </para>
3308
3309     <para>
3310      The <function>substring</> function with two parameters,
3311      <function>substring(<replaceable>string</replaceable> from
3312      <replaceable>pattern</replaceable>)</function>, provides extraction of a
3313      substring
3314      that matches a POSIX regular expression pattern.  It returns null if
3315      there is no match, otherwise the portion of the text that matched the
3316      pattern.  But if the pattern contains any parentheses, the portion
3317      of the text that matched the first parenthesized subexpression (the
3318      one whose left parenthesis comes first) is
3319      returned.  You can put parentheses around the whole expression
3320      if you want to use parentheses within it without triggering this
3321      exception.  If you need parentheses in the pattern before the
3322      subexpression you want to extract, see the non-capturing parentheses
3323      described below.
3324     </para>
3325
3326    <para>
3327     Some examples:
3328 <programlisting>
3329 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
3330 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
3331 </programlisting>
3332    </para>
3333
3334     <para>
3335      The <function>regexp_replace</> function provides substitution of
3336      new text for substrings that match POSIX regular expression patterns.
3337      It has the syntax
3338      <function>regexp_replace</function>(<replaceable>source</>,
3339      <replaceable>pattern</>, <replaceable>replacement</>
3340      <optional>, <replaceable>flags</> </optional>).
3341      The <replaceable>source</> string is returned unchanged if
3342      there is no match to the <replaceable>pattern</>.  If there is a
3343      match, the <replaceable>source</> string is returned with the
3344      <replaceable>replacement</> string substituted for the matching
3345      substring.  The <replaceable>replacement</> string can contain
3346      <literal>\</><replaceable>n</>, where <replaceable>n</> is <literal>1</>
3347      through <literal>9</>, to indicate that the source substring matching the
3348      <replaceable>n</>'th parenthesized subexpression of the pattern should be
3349      inserted, and it can contain <literal>\&amp;</> to indicate that the
3350      substring matching the entire pattern should be inserted.  Write
3351      <literal>\\</> if you need to put a literal backslash in the replacement
3352      text.  (As always, remember to double backslashes written in literal
3353      constant strings, assuming escape string syntax is used.)
3354      The <replaceable>flags</> parameter is an optional text
3355      string containing zero or more single-letter flags that change the
3356      function's behavior.  Flag <literal>i</> specifies case-insensitive
3357      matching, while flag <literal>g</> specifies replacement of each matching
3358      substring rather than only the first one.  Other supported flags are
3359      described in <xref linkend="posix-embedded-options-table">.
3360     </para>
3361
3362    <para>
3363     Some examples:
3364 <programlisting>
3365 regexp_replace('foobarbaz', 'b..', 'X')
3366                                    <lineannotation>fooXbaz</lineannotation>
3367 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3368                                    <lineannotation>fooXX</lineannotation>
3369 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3370                                    <lineannotation>fooXarYXazY</lineannotation>
3371 </programlisting>
3372    </para>
3373
3374     <para>
3375      The <function>regexp_matches</> function returns all of the captured
3376      substrings resulting from matching a POSIX regular expression pattern.
3377      It has the syntax
3378      <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3379      <optional>, <replaceable>flags</> </optional>).
3380      If there is no match to the <replaceable>pattern</>, the function returns
3381      no rows.  If there is a match, the function returns a text array whose
3382      <replaceable>n</>'th element is the substring matching the
3383      <replaceable>n</>'th parenthesized subexpression of the pattern
3384      (not counting <quote>non-capturing</> parentheses; see below for
3385      details).  If the pattern does not contain any parenthesized
3386      subexpressions, then the result is a single-element text array containing
3387      the substring matching the whole pattern.
3388      The <replaceable>flags</> parameter is an optional text
3389      string containing zero or more single-letter flags that change the
3390      function's behavior.  Flag <literal>g</> causes the function to find
3391      each match in the string, not only the first one, and return a row for
3392      each such match.  Other supported
3393      flags are described in <xref linkend="posix-embedded-options-table">.
3394     </para>
3395
3396    <para>
3397     Some examples:
3398 <programlisting>
3399 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3400  regexp_matches 
3401 ----------------
3402  {bar,beque}
3403 (1 row)
3404
3405 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3406  regexp_matches 
3407 ----------------
3408  {bar,beque}
3409  {bazil,barf}
3410 (2 rows)
3411
3412 SELECT regexp_matches('foobarbequebaz', 'barbeque');
3413  regexp_matches 
3414 ----------------
3415  {barbeque}
3416 (1 row)
3417 </programlisting>
3418    </para>
3419
3420     <para>
3421      The <function>regexp_split_to_table</> function splits a string using a POSIX
3422      regular expression pattern as a delimiter.  It has the syntax
3423      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
3424      <optional>, <replaceable>flags</> </optional>).
3425      If there is no match to the <replaceable>pattern</>, the function returns the
3426      <replaceable>string</>.  If there is at least one match, for each match it returns
3427      the text from the end of the last match (or the beginning of the string)
3428      to the beginning of the match.  When there are no more matches, it
3429      returns the text from the end of the last match to the end of the string.
3430      The <replaceable>flags</> parameter is an optional text string containing
3431      zero or more single-letter flags that change the function's behavior.
3432      <function>regexp_split_to_table</function> supports the flags described in
3433      <xref linkend="posix-embedded-options-table">.
3434     </para>
3435
3436     <para>
3437      The <function>regexp_split_to_array</> function behaves the same as
3438      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
3439      returns its result as an array of <type>text</>.  It has the syntax
3440      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
3441      <optional>, <replaceable>flags</> </optional>).
3442      The parameters are the same as for <function>regexp_split_to_table</>.
3443     </para>
3444
3445    <para>
3446     Some examples:
3447 <programlisting>
3448
3449 SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\\s+') AS foo;
3450   foo   
3451 --------
3452  the    
3453  quick  
3454  brown  
3455  fox    
3456  jumped 
3457  over   
3458  the    
3459  lazy   
3460  dog    
3461 (9 rows)
3462
3463 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
3464               regexp_split_to_array             
3465 ------------------------------------------------
3466  {the,quick,brown,fox,jumped,over,the,lazy,dog}
3467 (1 row)
3468
3469 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
3470  foo 
3471 -----
3472  t         
3473  h         
3474  e         
3475  q         
3476  u         
3477  i         
3478  c         
3479  k         
3480  b         
3481  r         
3482  o         
3483  w         
3484  n         
3485  f         
3486  o         
3487  x         
3488 (16 rows)
3489 </programlisting>
3490    </para>
3491
3492    <para>
3493     As the last example demonstrates, the regexp split functions ignore
3494     zero-length matches that occur at the start or end of the string
3495     or immediately after a previous match.  This is contrary to the strict
3496     definition of regexp matching that is implemented by
3497     <function>regexp_matches</>, but is usually the most convenient behavior
3498     in practice.  Other software systems such as Perl use similar definitions.
3499    </para>
3500
3501 <!-- derived from the re_syntax.n man page -->
3502
3503    <sect3 id="posix-syntax-details">
3504     <title>Regular Expression Details</title>
3505
3506    <para>
3507     <productname>PostgreSQL</productname>'s regular expressions are implemented
3508     using a package written by Henry Spencer.  Much of
3509     the description of regular expressions below is copied verbatim from his
3510     manual entry.
3511    </para>
3512
3513    <para>
3514     Regular expressions (<acronym>RE</acronym>s), as defined in
3515     <acronym>POSIX</acronym> 1003.2, come in two forms:
3516     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
3517     (roughly those of <command>egrep</command>), and
3518     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
3519     (roughly those of <command>ed</command>).
3520     <productname>PostgreSQL</productname> supports both forms, and
3521     also implements some extensions
3522     that are not in the POSIX standard, but have become widely used anyway
3523     due to their availability in programming languages such as Perl and Tcl.
3524     <acronym>RE</acronym>s using these non-POSIX extensions are called
3525     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
3526     in this documentation.  AREs are almost an exact superset of EREs,
3527     but BREs have several notational incompatibilities (as well as being
3528     much more limited).
3529     We first describe the ARE and ERE forms, noting features that apply
3530     only to AREs, and then describe how BREs differ.
3531    </para>
3532
3533    <note>
3534     <para>
3535      The form of regular expressions accepted by
3536      <productname>PostgreSQL</> can be chosen by setting the <xref
3537      linkend="guc-regex-flavor"> run-time parameter.  The usual
3538      setting is <literal>advanced</>, but one might choose
3539      <literal>extended</> for maximum backwards compatibility with
3540      pre-7.4 releases of <productname>PostgreSQL</>.
3541     </para>
3542    </note>
3543
3544    <para>
3545     A regular expression is defined as one or more
3546     <firstterm>branches</firstterm>, separated by
3547     <literal>|</literal>.  It matches anything that matches one of the
3548     branches.
3549    </para>
3550
3551    <para>
3552     A branch is zero or more <firstterm>quantified atoms</> or
3553     <firstterm>constraints</>, concatenated.
3554     It matches a match for the first, followed by a match for the second, etc;
3555     an empty branch matches the empty string.
3556    </para>
3557
3558    <para>
3559     A quantified atom is an <firstterm>atom</> possibly followed
3560     by a single <firstterm>quantifier</>.
3561     Without a quantifier, it matches a match for the atom.
3562     With a quantifier, it can match some number of matches of the atom.
3563     An <firstterm>atom</firstterm> can be any of the possibilities
3564     shown in <xref linkend="posix-atoms-table">.
3565     The possible quantifiers and their meanings are shown in
3566     <xref linkend="posix-quantifiers-table">.
3567    </para>
3568
3569    <para>
3570     A <firstterm>constraint</> matches an empty string, but matches only when
3571     specific conditions are met.  A constraint can be used where an atom
3572     could be used, except it cannot be followed by a quantifier.
3573     The simple constraints are shown in
3574     <xref linkend="posix-constraints-table">;
3575     some more constraints are described later.
3576    </para>
3577
3578
3579    <table id="posix-atoms-table">
3580     <title>Regular Expression Atoms</title>
3581
3582     <tgroup cols="2">
3583      <thead>
3584       <row>
3585        <entry>Atom</entry>
3586        <entry>Description</entry>
3587       </row>
3588      </thead>
3589
3590       <tbody>
3591        <row>
3592        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3593        <entry> (where <replaceable>re</> is any regular expression)
3594        matches a match for
3595        <replaceable>re</>, with the match noted for possible reporting </entry>
3596        </row>
3597
3598        <row>
3599        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3600        <entry> as above, but the match is not noted for reporting
3601        (a <quote>non-capturing</> set of parentheses)
3602        (AREs only) </entry>
3603        </row>
3604
3605        <row>
3606        <entry> <literal>.</> </entry>
3607        <entry> matches any single character </entry>
3608        </row>
3609
3610        <row>
3611        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
3612        <entry> a <firstterm>bracket expression</>,
3613        matching any one of the <replaceable>chars</> (see
3614        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
3615        </row>
3616
3617        <row>
3618        <entry> <literal>\</><replaceable>k</> </entry>
3619        <entry> (where <replaceable>k</> is a non-alphanumeric character)
3620        matches that character taken as an ordinary character,
3621        e.g. <literal>\\</> matches a backslash character </entry>
3622        </row>
3623
3624        <row>
3625        <entry> <literal>\</><replaceable>c</> </entry>
3626        <entry> where <replaceable>c</> is alphanumeric
3627        (possibly followed by other characters)
3628        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
3629        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
3630        </row>
3631
3632        <row>
3633        <entry> <literal>{</> </entry>
3634        <entry> when followed by a character other than a digit,
3635        matches the left-brace character <literal>{</>;
3636        when followed by a digit, it is the beginning of a
3637        <replaceable>bound</> (see below) </entry>
3638        </row>
3639
3640        <row>
3641        <entry> <replaceable>x</> </entry>
3642        <entry> where <replaceable>x</> is a single character with no other
3643        significance, matches that character </entry>
3644        </row>
3645       </tbody>
3646      </tgroup>
3647     </table>
3648
3649    <para>
3650     An RE cannot end with <literal>\</>.
3651    </para>
3652
3653    <note>
3654     <para>
3655      Remember that the backslash (<literal>\</literal>) already has a special
3656      meaning in <productname>PostgreSQL</> string literals.
3657      To write a pattern constant that contains a backslash,
3658      you must write two backslashes in the statement, assuming escape
3659      string syntax is used (see <xref linkend="sql-syntax-strings">).
3660     </para>
3661    </note>
3662
3663    <table id="posix-quantifiers-table">
3664     <title>Regular Expression Quantifiers</title>
3665
3666     <tgroup cols="2">
3667      <thead>
3668       <row>
3669        <entry>Quantifier</entry>
3670        <entry>Matches</entry>
3671       </row>
3672      </thead>
3673
3674       <tbody>
3675        <row>
3676        <entry> <literal>*</> </entry>
3677        <entry> a sequence of 0 or more matches of the atom </entry>
3678        </row>
3679
3680        <row>
3681        <entry> <literal>+</> </entry>
3682        <entry> a sequence of 1 or more matches of the atom </entry>
3683        </row>
3684
3685        <row>
3686        <entry> <literal>?</> </entry>
3687        <entry> a sequence of 0 or 1 matches of the atom </entry>
3688        </row>
3689
3690        <row>
3691        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
3692        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
3693        </row>
3694
3695        <row>
3696        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
3697        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
3698        </row>
3699
3700        <row>
3701        <entry>
3702        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3703        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
3704        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
3705        <replaceable>n</> </entry>
3706        </row>
3707
3708        <row>
3709        <entry> <literal>*?</> </entry>
3710        <entry> non-greedy version of <literal>*</> </entry>
3711        </row>
3712
3713        <row>
3714        <entry> <literal>+?</> </entry>
3715        <entry> non-greedy version of <literal>+</> </entry>
3716        </row>
3717
3718        <row>
3719        <entry> <literal>??</> </entry>
3720        <entry> non-greedy version of <literal>?</> </entry>
3721        </row>
3722
3723        <row>
3724        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
3725        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
3726        </row>
3727
3728        <row>
3729        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
3730        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
3731        </row>
3732
3733        <row>
3734        <entry>
3735        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
3736        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3737        </row>
3738       </tbody>
3739      </tgroup>
3740     </table>
3741
3742    <para>
3743     The forms using <literal>{</><replaceable>...</><literal>}</>
3744     are known as <firstterm>bounds</>.
3745     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
3746     unsigned decimal integers with permissible values from 0 to 255 inclusive.
3747    </para>
3748
3749     <para>
3750      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
3751      same possibilities as their corresponding normal (<firstterm>greedy</>)
3752      counterparts, but prefer the smallest number rather than the largest
3753      number of matches.
3754      See <xref linkend="posix-matching-rules"> for more detail.
3755    </para>
3756
3757    <note>
3758     <para>
3759      A quantifier cannot immediately follow another quantifier.
3760      A quantifier cannot
3761      begin an expression or subexpression or follow
3762      <literal>^</literal> or <literal>|</literal>.
3763     </para>
3764    </note>
3765
3766    <table id="posix-constraints-table">
3767     <title>Regular Expression Constraints</title>
3768
3769     <tgroup cols="2">
3770      <thead>
3771       <row>
3772        <entry>Constraint</entry>
3773        <entry>Description</entry>
3774       </row>
3775      </thead>
3776
3777       <tbody>
3778        <row>
3779        <entry> <literal>^</> </entry>
3780        <entry> matches at the beginning of the string </entry>
3781        </row>
3782
3783        <row>
3784        <entry> <literal>$</> </entry>
3785        <entry> matches at the end of the string </entry>
3786        </row>
3787
3788        <row>
3789        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
3790        <entry> <firstterm>positive lookahead</> matches at any point
3791        where a substring matching <replaceable>re</> begins
3792        (AREs only) </entry>
3793        </row>
3794
3795        <row>
3796        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
3797        <entry> <firstterm>negative lookahead</> matches at any point
3798        where no substring matching <replaceable>re</> begins
3799        (AREs only) </entry>
3800        </row>
3801       </tbody>
3802      </tgroup>
3803     </table>
3804
3805    <para>
3806     Lookahead constraints cannot contain <firstterm>back references</>
3807     (see <xref linkend="posix-escape-sequences">),
3808     and all parentheses within them are considered non-capturing.
3809    </para>
3810    </sect3>
3811
3812    <sect3 id="posix-bracket-expressions">
3813     <title>Bracket Expressions</title>
3814
3815    <para>
3816     A <firstterm>bracket expression</firstterm> is a list of
3817     characters enclosed in <literal>[]</literal>.  It normally matches
3818     any single character from the list (but see below).  If the list
3819     begins with <literal>^</literal>, it matches any single character
3820     <emphasis>not</> from the rest of the list.
3821     If two characters
3822     in the list are separated by <literal>-</literal>, this is
3823     shorthand for the full range of characters between those two
3824     (inclusive) in the collating sequence,
3825     e.g. <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
3826     any decimal digit.  It is illegal for two ranges to share an
3827     endpoint, e.g.  <literal>a-c-e</literal>.  Ranges are very
3828     collating-sequence-dependent, so portable programs should avoid
3829     relying on them.
3830    </para>
3831
3832    <para>
3833     To include a literal <literal>]</literal> in the list, make it the
3834     first character (following a possible <literal>^</literal>).  To
3835     include a literal <literal>-</literal>, make it the first or last
3836     character, or the second endpoint of a range.  To use a literal
3837     <literal>-</literal> as the first endpoint of a range, enclose it
3838     in <literal>[.</literal> and <literal>.]</literal> to make it a
3839     collating element (see below).  With the exception of these characters,
3840     some combinations using <literal>[</literal>
3841     (see next paragraphs), and escapes (AREs only), all other special
3842     characters lose their special significance within a bracket expression.
3843     In particular, <literal>\</literal> is not special when following
3844     ERE or BRE rules, though it is special (as introducing an escape)
3845     in AREs.
3846    </para>
3847
3848    <para>
3849     Within a bracket expression, a collating element (a character, a
3850     multiple-character sequence that collates as if it were a single
3851     character, or a collating-sequence name for either) enclosed in
3852     <literal>[.</literal> and <literal>.]</literal> stands for the
3853     sequence of characters of that collating element.  The sequence is
3854     a single element of the bracket expression's list.  A bracket
3855     expression containing a multiple-character collating element can thus
3856     match more than one character, e.g. if the collating sequence
3857     includes a <literal>ch</literal> collating element, then the RE
3858     <literal>[[.ch.]]*c</literal> matches the first five characters of
3859     <literal>chchcc</literal>.
3860    </para>
3861
3862    <note>
3863     <para>
3864      <productname>PostgreSQL</> currently has no multicharacter collating
3865      elements. This information describes possible future behavior.
3866     </para>
3867    </note>
3868
3869    <para>
3870     Within a bracket expression, a collating element enclosed in
3871     <literal>[=</literal> and <literal>=]</literal> is an equivalence
3872     class, standing for the sequences of characters of all collating
3873     elements equivalent to that one, including itself.  (If there are
3874     no other equivalent collating elements, the treatment is as if the
3875     enclosing delimiters were <literal>[.</literal> and
3876     <literal>.]</literal>.)  For example, if <literal>o</literal> and
3877     <literal>^</literal> are the members of an equivalence class, then
3878     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
3879     <literal>[o^]</literal> are all synonymous.  An equivalence class
3880     cannot be an endpoint of a range.
3881    </para>
3882
3883    <para>
3884     Within a bracket expression, the name of a character class
3885     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
3886     for the list of all characters belonging to that class.  Standard
3887     character class names are: <literal>alnum</literal>,
3888     <literal>alpha</literal>, <literal>blank</literal>,
3889     <literal>cntrl</literal>, <literal>digit</literal>,
3890     <literal>graph</literal>, <literal>lower</literal>,
3891     <literal>print</literal>, <literal>punct</literal>,
3892     <literal>space</literal>, <literal>upper</literal>,
3893     <literal>xdigit</literal>.  These stand for the character classes
3894     defined in
3895     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
3896     A locale can provide others.  A character class cannot be used as
3897     an endpoint of a range.
3898    </para>
3899
3900    <para>
3901     There are two special cases of bracket expressions:  the bracket
3902     expressions <literal>[[:&lt;:]]</literal> and
3903     <literal>[[:&gt;:]]</literal> are constraints,
3904     matching empty strings at the beginning
3905     and end of a word respectively.  A word is defined as a sequence
3906     of word characters that is neither preceded nor followed by word
3907     characters.  A word character is an <literal>alnum</> character (as
3908     defined by
3909     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
3910     or an underscore.  This is an extension, compatible with but not
3911     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
3912     caution in software intended to be portable to other systems.
3913     The constraint escapes described below are usually preferable (they
3914     are no more standard, but are certainly easier to type).
3915    </para>
3916    </sect3>
3917
3918    <sect3 id="posix-escape-sequences">
3919     <title>Regular Expression Escapes</title>
3920
3921    <para>
3922     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
3923     followed by an alphanumeric character. Escapes come in several varieties:
3924     character entry, class shorthands, constraint escapes, and back references.
3925     A <literal>\</> followed by an alphanumeric character but not constituting
3926     a valid escape is illegal in AREs.
3927     In EREs, there are no escapes: outside a bracket expression,
3928     a <literal>\</> followed by an alphanumeric character merely stands for
3929     that character as an ordinary character, and inside a bracket expression,
3930     <literal>\</> is an ordinary character.
3931     (The latter is the one actual incompatibility between EREs and AREs.)
3932    </para>
3933
3934    <para>
3935     <firstterm>Character-entry escapes</> exist to make it easier to specify
3936     non-printing and otherwise inconvenient characters in REs.  They are
3937     shown in <xref linkend="posix-character-entry-escapes-table">.
3938    </para>
3939
3940    <para>
3941     <firstterm>Class-shorthand escapes</> provide shorthands for certain
3942     commonly-used character classes.  They are
3943     shown in <xref linkend="posix-class-shorthand-escapes-table">.
3944    </para>
3945
3946    <para>
3947     A <firstterm>constraint escape</> is a constraint,
3948     matching the empty string if specific conditions are met,
3949     written as an escape.  They are
3950     shown in <xref linkend="posix-constraint-escapes-table">.
3951    </para>
3952
3953    <para>
3954     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
3955     same string matched by the previous parenthesized subexpression specified
3956     by the number <replaceable>n</>
3957     (see <xref linkend="posix-constraint-backref-table">).  For example,
3958     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
3959     but not <literal>bc</> or <literal>cb</>.
3960     The subexpression must entirely precede the back reference in the RE.
3961     Subexpressions are numbered in the order of their leading parentheses.
3962     Non-capturing parentheses do not define subexpressions.
3963    </para>
3964
3965    <note>
3966     <para>
3967      Keep in mind that an escape's leading <literal>\</> will need to be
3968      doubled when entering the pattern as an SQL string constant.  For example:
3969 <programlisting>
3970 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
3971 </programlisting>
3972     </para>
3973    </note>
3974
3975    <table id="posix-character-entry-escapes-table">
3976     <title>Regular Expression Character-Entry Escapes</title>
3977
3978     <tgroup cols="2">
3979      <thead>
3980       <row>
3981        <entry>Escape</entry>
3982        <entry>Description</entry>
3983       </row>
3984      </thead>
3985
3986       <tbody>
3987        <row>
3988        <entry> <literal>\a</> </entry>
3989        <entry> alert (bell) character, as in C </entry>
3990        </row>
3991
3992        <row>
3993        <entry> <literal>\b</> </entry>
3994        <entry> backspace, as in C </entry>
3995        </row>
3996
3997        <row>
3998        <entry> <literal>\B</> </entry>
3999        <entry> synonym for <literal>\</> to help reduce the need for backslash
4000        doubling </entry>
4001        </row>
4002
4003        <row>
4004        <entry> <literal>\c</><replaceable>X</> </entry>
4005        <entry> (where <replaceable>X</> is any character) the character whose
4006        low-order 5 bits are the same as those of
4007        <replaceable>X</>, and whose other bits are all zero </entry>
4008        </row>
4009
4010        <row>
4011        <entry> <literal>\e</> </entry>
4012        <entry> the character whose collating-sequence name
4013        is <literal>ESC</>,
4014        or failing that, the character with octal value 033 </entry>
4015        </row>
4016
4017        <row>
4018        <entry> <literal>\f</> </entry>
4019        <entry> form feed, as in C </entry>
4020        </row>
4021
4022        <row>
4023        <entry> <literal>\n</> </entry>
4024        <entry> newline, as in C </entry>
4025        </row>
4026
4027        <row>
4028        <entry> <literal>\r</> </entry>
4029        <entry> carriage return, as in C </entry>
4030        </row>
4031
4032        <row>
4033        <entry> <literal>\t</> </entry>
4034        <entry> horizontal tab, as in C </entry>
4035        </row>
4036
4037        <row>
4038        <entry> <literal>\u</><replaceable>wxyz</> </entry>
4039        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4040        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4041        in the local byte ordering </entry>
4042        </row>
4043
4044        <row>
4045        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4046        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4047        digits)
4048        reserved for a somewhat-hypothetical Unicode extension to 32 bits
4049        </entry> 
4050        </row>
4051
4052        <row>
4053        <entry> <literal>\v</> </entry>
4054        <entry> vertical tab, as in C </entry>
4055        </row>
4056
4057        <row>
4058        <entry> <literal>\x</><replaceable>hhh</> </entry>
4059        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4060        digits)
4061        the character whose hexadecimal value is
4062        <literal>0x</><replaceable>hhh</>
4063        (a single character no matter how many hexadecimal digits are used)
4064        </entry>
4065        </row>
4066
4067        <row>
4068        <entry> <literal>\0</> </entry>
4069        <entry> the character whose value is <literal>0</> </entry>
4070        </row>
4071
4072        <row>
4073        <entry> <literal>\</><replaceable>xy</> </entry>
4074        <entry> (where <replaceable>xy</> is exactly two octal digits,
4075        and is not a <firstterm>back reference</>)
4076        the character whose octal value is
4077        <literal>0</><replaceable>xy</> </entry>
4078        </row>
4079
4080        <row>
4081        <entry> <literal>\</><replaceable>xyz</> </entry>
4082        <entry> (where <replaceable>xyz</> is exactly three octal digits,
4083        and is not a <firstterm>back reference</>)
4084        the character whose octal value is
4085        <literal>0</><replaceable>xyz</> </entry>
4086        </row>
4087       </tbody>
4088      </tgroup>
4089     </table>
4090
4091    <para>
4092     Hexadecimal digits are <literal>0</>-<literal>9</>,
4093     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4094     Octal digits are <literal>0</>-<literal>7</>.
4095    </para>
4096
4097    <para>
4098     The character-entry escapes are always taken as ordinary characters.
4099     For example, <literal>\135</> is <literal>]</> in ASCII, but
4100     <literal>\135</> does not terminate a bracket expression.
4101    </para>
4102
4103    <table id="posix-class-shorthand-escapes-table">
4104     <title>Regular Expression Class-Shorthand Escapes</title>
4105
4106     <tgroup cols="2">
4107      <thead>
4108       <row>
4109        <entry>Escape</entry>
4110        <entry>Description</entry>
4111       </row>
4112      </thead>
4113
4114       <tbody>
4115        <row>
4116        <entry> <literal>\d</> </entry>
4117        <entry> <literal>[[:digit:]]</> </entry>
4118        </row>
4119
4120        <row>
4121        <entry> <literal>\s</> </entry>
4122        <entry> <literal>[[:space:]]</> </entry>
4123        </row>
4124
4125        <row>
4126        <entry> <literal>\w</> </entry>
4127        <entry> <literal>[[:alnum:]_]</>
4128        (note underscore is included) </entry>
4129        </row>
4130
4131        <row>
4132        <entry> <literal>\D</> </entry>
4133        <entry> <literal>[^[:digit:]]</> </entry>
4134        </row>
4135
4136        <row>
4137        <entry> <literal>\S</> </entry>
4138        <entry> <literal>[^[:space:]]</> </entry>
4139        </row>
4140
4141        <row>
4142        <entry> <literal>\W</> </entry>
4143        <entry> <literal>[^[:alnum:]_]</>
4144        (note underscore is included) </entry>
4145        </row>
4146       </tbody>
4147      </tgroup>
4148     </table>
4149
4150    <para>
4151     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4152     and <literal>\w</> lose their outer brackets,
4153     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4154     (So, for example, <literal>[a-c\d]</> is equivalent to
4155     <literal>[a-c[:digit:]]</>.
4156     Also, <literal>[a-c\D]</>, which is equivalent to
4157     <literal>[a-c^[:digit:]]</>, is illegal.)
4158    </para>
4159
4160    <table id="posix-constraint-escapes-table">
4161     <title>Regular Expression Constraint Escapes</title>
4162
4163     <tgroup cols="2">
4164      <thead>
4165       <row>
4166        <entry>Escape</entry>
4167        <entry>Description</entry>
4168       </row>
4169      </thead>
4170
4171       <tbody>
4172        <row>
4173        <entry> <literal>\A</> </entry>
4174        <entry> matches only at the beginning of the string
4175        (see <xref linkend="posix-matching-rules"> for how this differs from
4176        <literal>^</>) </entry>
4177        </row>
4178
4179        <row>
4180        <entry> <literal>\m</> </entry>
4181        <entry> matches only at the beginning of a word </entry>
4182        </row>
4183
4184        <row>
4185        <entry> <literal>\M</> </entry>
4186        <entry> matches only at the end of a word </entry>
4187        </row>
4188
4189        <row>
4190        <entry> <literal>\y</> </entry>
4191        <entry> matches only at the beginning or end of a word </entry>
4192        </row>
4193
4194        <row>
4195        <entry> <literal>\Y</> </entry>
4196        <entry> matches only at a point that is not the beginning or end of a
4197        word </entry>
4198        </row>
4199
4200        <row>
4201        <entry> <literal>\Z</> </entry>
4202        <entry> matches only at the end of the string
4203        (see <xref linkend="posix-matching-rules"> for how this differs from
4204        <literal>$</>) </entry>
4205        </row>
4206       </tbody>
4207      </tgroup>
4208     </table>
4209
4210    <para>
4211     A word is defined as in the specification of
4212     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4213     Constraint escapes are illegal within bracket expressions.
4214    </para>
4215
4216    <table id="posix-constraint-backref-table">
4217     <title>Regular Expression Back References</title>
4218
4219     <tgroup cols="2">
4220      <thead>
4221       <row>
4222        <entry>Escape</entry>
4223        <entry>Description</entry>
4224       </row>
4225      </thead>
4226
4227       <tbody>
4228        <row>
4229        <entry> <literal>\</><replaceable>m</> </entry>
4230        <entry> (where <replaceable>m</> is a nonzero digit)
4231        a back reference to the <replaceable>m</>'th subexpression </entry>
4232        </row>
4233
4234        <row>
4235        <entry> <literal>\</><replaceable>mnn</> </entry>
4236        <entry> (where <replaceable>m</> is a nonzero digit, and
4237        <replaceable>nn</> is some more digits, and the decimal value
4238        <replaceable>mnn</> is not greater than the number of closing capturing
4239        parentheses seen so far) 
4240        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4241        </row>
4242       </tbody>
4243      </tgroup>
4244     </table>
4245
4246    <note>
4247     <para>
4248      There is an inherent historical ambiguity between octal character-entry 
4249      escapes and back references, which is resolved by heuristics,
4250      as hinted at above.
4251      A leading zero always indicates an octal escape.
4252      A single non-zero digit, not followed by another digit,
4253      is always taken as a back reference.
4254      A multidigit sequence not starting with a zero is taken as a back 
4255      reference if it comes after a suitable subexpression
4256      (i.e. the number is in the legal range for a back reference),
4257      and otherwise is taken as octal.
4258     </para>
4259    </note>
4260    </sect3>
4261
4262    <sect3 id="posix-metasyntax">
4263     <title>Regular Expression Metasyntax</title>
4264
4265    <para>
4266     In addition to the main syntax described above, there are some special
4267     forms and miscellaneous syntactic facilities available.
4268    </para>
4269
4270    <para>
4271     Normally the flavor of RE being used is determined by
4272     <varname>regex_flavor</>.
4273     However, this can be overridden by a <firstterm>director</> prefix.
4274     If an RE begins with <literal>***:</>,
4275     the rest of the RE is taken as an ARE regardless of
4276     <varname>regex_flavor</>.
4277     If an RE begins with <literal>***=</>,
4278     the rest of the RE is taken to be a literal string,
4279     with all characters considered ordinary characters.
4280    </para>
4281
4282    <para>
4283     An ARE can begin with <firstterm>embedded options</>:
4284     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4285     (where <replaceable>xyz</> is one or more alphabetic characters)
4286     specifies options affecting the rest of the RE.
4287     These options override any previously determined options (including
4288     both the RE flavor and case sensitivity).
4289     The available option letters are
4290     shown in <xref linkend="posix-embedded-options-table">.
4291    </para>
4292
4293    <table id="posix-embedded-options-table">
4294     <title>ARE Embedded-Option Letters</title>
4295
4296     <tgroup cols="2">
4297      <thead>
4298       <row>
4299        <entry>Option</entry>
4300        <entry>Description</entry>
4301       </row>
4302      </thead>
4303
4304       <tbody>
4305        <row>
4306        <entry> <literal>b</> </entry>
4307        <entry> rest of RE is a BRE </entry>
4308        </row>
4309
4310        <row>
4311        <entry> <literal>c</> </entry>
4312        <entry> case-sensitive matching (overrides operator type) </entry>
4313        </row>
4314
4315        <row>
4316        <entry> <literal>e</> </entry>
4317        <entry> rest of RE is an ERE </entry>
4318        </row>
4319
4320        <row>
4321        <entry> <literal>i</> </entry>
4322        <entry> case-insensitive matching (see
4323        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4324        </row>
4325
4326        <row>
4327        <entry> <literal>m</> </entry>
4328        <entry> historical synonym for <literal>n</> </entry>
4329        </row>
4330
4331        <row>
4332        <entry> <literal>n</> </entry>
4333        <entry> newline-sensitive matching (see
4334        <xref linkend="posix-matching-rules">) </entry>
4335        </row>
4336
4337        <row>
4338        <entry> <literal>p</> </entry>
4339        <entry> partial newline-sensitive matching (see
4340        <xref linkend="posix-matching-rules">) </entry>
4341        </row>
4342
4343        <row>
4344        <entry> <literal>q</> </entry>
4345        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4346        characters </entry>
4347        </row>
4348
4349        <row>
4350        <entry> <literal>s</> </entry>
4351        <entry> non-newline-sensitive matching (default) </entry>
4352        </row>
4353
4354        <row>
4355        <entry> <literal>t</> </entry>
4356        <entry> tight syntax (default; see below) </entry>
4357        </row>
4358
4359        <row>
4360        <entry> <literal>w</> </entry>
4361        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4362        (see <xref linkend="posix-matching-rules">) </entry>
4363        </row>
4364
4365        <row>
4366        <entry> <literal>x</> </entry>
4367        <entry> expanded syntax (see below) </entry>
4368        </row>
4369       </tbody>
4370      </tgroup>
4371     </table>
4372
4373    <para>
4374     Embedded options take effect at the <literal>)</> terminating the sequence.
4375     They can appear only at the start of an ARE (after the
4376     <literal>***:</> director if any).
4377    </para>
4378
4379    <para>
4380     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4381     characters are significant, there is an <firstterm>expanded</> syntax,
4382     available by specifying the embedded <literal>x</> option.
4383     In the expanded syntax,
4384     white-space characters in the RE are ignored, as are
4385     all characters between a <literal>#</>
4386     and the following newline (or the end of the RE).  This
4387     permits paragraphing and commenting a complex RE.
4388     There are three exceptions to that basic rule:
4389
4390     <itemizedlist>
4391      <listitem>
4392       <para>
4393        a white-space character or <literal>#</> preceded by <literal>\</> is
4394        retained
4395       </para>
4396      </listitem>
4397      <listitem>
4398       <para>
4399        white space or <literal>#</> within a bracket expression is retained
4400       </para>
4401      </listitem>
4402      <listitem>
4403       <para>
4404        white space and comments cannot appear within multicharacter symbols,
4405        such as <literal>(?:</>
4406       </para>
4407      </listitem>
4408     </itemizedlist>
4409
4410     For this purpose, white-space characters are blank, tab, newline, and
4411     any character that belongs to the <replaceable>space</> character class.
4412    </para>
4413
4414    <para>
4415     Finally, in an ARE, outside bracket expressions, the sequence
4416     <literal>(?#</><replaceable>ttt</><literal>)</>
4417     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4418     is a comment, completely ignored.
4419     Again, this is not allowed between the characters of
4420     multicharacter symbols, like <literal>(?:</>.
4421     Such comments are more a historical artifact than a useful facility,
4422     and their use is deprecated; use the expanded syntax instead.
4423    </para>
4424
4425    <para>
4426     <emphasis>None</> of these metasyntax extensions is available if
4427     an initial <literal>***=</> director
4428     has specified that the user's input be treated as a literal string
4429     rather than as an RE.
4430    </para>
4431    </sect3>
4432
4433    <sect3 id="posix-matching-rules">
4434     <title>Regular Expression Matching Rules</title>
4435
4436    <para>
4437     In the event that an RE could match more than one substring of a given
4438     string, the RE matches the one starting earliest in the string.
4439     If the RE could match more than one substring starting at that point,
4440     either the longest possible match or the shortest possible match will
4441     be taken, depending on whether the RE is <firstterm>greedy</> or
4442     <firstterm>non-greedy</>.
4443    </para>
4444
4445    <para>
4446     Whether an RE is greedy or not is determined by the following rules:
4447     <itemizedlist>
4448      <listitem>
4449       <para>
4450        Most atoms, and all constraints, have no greediness attribute (because
4451        they cannot match variable amounts of text anyway).
4452       </para>
4453      </listitem>
4454      <listitem>
4455       <para>
4456        Adding parentheses around an RE does not change its greediness.
4457       </para>
4458      </listitem>
4459      <listitem>
4460       <para>
4461        A quantified atom with a fixed-repetition quantifier
4462        (<literal>{</><replaceable>m</><literal>}</>
4463        or
4464        <literal>{</><replaceable>m</><literal>}?</>)
4465        has the same greediness (possibly none) as the atom itself.
4466       </para>
4467      </listitem>
4468      <listitem>
4469       <para>
4470        A quantified atom with other normal quantifiers (including
4471        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4472        with <replaceable>m</> equal to <replaceable>n</>)
4473        is greedy (prefers longest match).
4474       </para>
4475      </listitem>
4476      <listitem>
4477       <para>
4478        A quantified atom with a non-greedy quantifier (including
4479        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4480        with <replaceable>m</> equal to <replaceable>n</>)
4481        is non-greedy (prefers shortest match).
4482       </para>
4483      </listitem>
4484      <listitem>
4485       <para>
4486        A branch &mdash; that is, an RE that has no top-level
4487        <literal>|</> operator &mdash; has the same greediness as the first
4488        quantified atom in it that has a greediness attribute.
4489       </para>
4490      </listitem>
4491      <listitem>
4492       <para>
4493        An RE consisting of two or more branches connected by the
4494        <literal>|</> operator is always greedy.
4495       </para>
4496      </listitem>
4497     </itemizedlist>
4498    </para>
4499
4500    <para>
4501     The above rules associate greediness attributes not only with individual
4502     quantified atoms, but with branches and entire REs that contain quantified
4503     atoms.  What that means is that the matching is done in such a way that
4504     the branch, or whole RE, matches the longest or shortest possible
4505     substring <emphasis>as a whole</>.  Once the length of the entire match
4506     is determined, the part of it that matches any particular subexpression
4507     is determined on the basis of the greediness attribute of that
4508     subexpression, with subexpressions starting earlier in the RE taking
4509     priority over ones starting later.
4510    </para>
4511
4512    <para>
4513     An example of what this means:
4514 <screen>
4515 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4516 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4517 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4518 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4519 </screen>
4520     In the first case, the RE as a whole is greedy because <literal>Y*</>
4521     is greedy.  It can match beginning at the <literal>Y</>, and it matches
4522     the longest possible string starting there, i.e., <literal>Y123</>.
4523     The output is the parenthesized part of that, or <literal>123</>.
4524     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4525     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
4526     the shortest possible string starting there, i.e., <literal>Y1</>.
4527     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4528     the decision as to the overall match length; so it is forced to match
4529     just <literal>1</>.
4530    </para>
4531
4532    <para>
4533     In short, when an RE contains both greedy and non-greedy subexpressions,
4534     the total match length is either as long as possible or as short as
4535     possible, according to the attribute assigned to the whole RE.  The
4536     attributes assigned to the subexpressions only affect how much of that
4537     match they are allowed to <quote>eat</> relative to each other.
4538    </para>
4539
4540    <para>
4541     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4542     can be used to force greediness or non-greediness, respectively,
4543     on a subexpression or a whole RE.
4544    </para>
4545
4546    <para>
4547     Match lengths are measured in characters, not collating elements.
4548     An empty string is considered longer than no match at all.
4549     For example:
4550     <literal>bb*</>
4551     matches the three middle characters of <literal>abbbc</>;
4552     <literal>(week|wee)(night|knights)</>
4553     matches all ten characters of <literal>weeknights</>;
4554     when <literal>(.*).*</>
4555     is matched against <literal>abc</> the parenthesized subexpression
4556     matches all three characters; and when
4557     <literal>(a*)*</> is matched against <literal>bc</>
4558     both the whole RE and the parenthesized
4559     subexpression match an empty string.
4560    </para>
4561
4562    <para>
4563     If case-independent matching is specified,
4564     the effect is much as if all case distinctions had vanished from the
4565     alphabet.
4566     When an alphabetic that exists in multiple cases appears as an
4567     ordinary character outside a bracket expression, it is effectively
4568     transformed into a bracket expression containing both cases,
4569     e.g. <literal>x</> becomes <literal>[xX]</>.
4570     When it appears inside a bracket expression, all case counterparts
4571     of it are added to the bracket expression, e.g.
4572     <literal>[x]</> becomes <literal>[xX]</>
4573     and <literal>[^x]</> becomes <literal>[^xX]</>.
4574    </para>
4575
4576    <para>
4577     If newline-sensitive matching is specified, <literal>.</>
4578     and bracket expressions using <literal>^</>
4579     will never match the newline character
4580     (so that matches will never cross newlines unless the RE
4581     explicitly arranges it)
4582     and <literal>^</>and <literal>$</>
4583     will match the empty string after and before a newline
4584     respectively, in addition to matching at beginning and end of string
4585     respectively.
4586     But the ARE escapes <literal>\A</> and <literal>\Z</>
4587     continue to match beginning or end of string <emphasis>only</>.
4588    </para>
4589
4590    <para>
4591     If partial newline-sensitive matching is specified,
4592     this affects <literal>.</> and bracket expressions
4593     as with newline-sensitive matching, but not <literal>^</>
4594     and <literal>$</>.
4595    </para>
4596
4597    <para>
4598     If inverse partial newline-sensitive matching is specified,
4599     this affects <literal>^</> and <literal>$</>
4600     as with newline-sensitive matching, but not <literal>.</>
4601     and bracket expressions.
4602     This isn't very useful but is provided for symmetry.
4603    </para>
4604    </sect3>
4605
4606    <sect3 id="posix-limits-compatibility">
4607     <title>Limits and Compatibility</title>
4608
4609    <para>
4610     No particular limit is imposed on the length of REs in this
4611     implementation.  However,
4612     programs intended to be highly portable should not employ REs longer
4613     than 256 bytes,
4614     as a POSIX-compliant implementation can refuse to accept such REs.
4615    </para>
4616
4617    <para>
4618     The only feature of AREs that is actually incompatible with
4619     POSIX EREs is that <literal>\</> does not lose its special
4620     significance inside bracket expressions.
4621     All other ARE features use syntax which is illegal or has
4622     undefined or unspecified effects in POSIX EREs;
4623     the <literal>***</> syntax of directors likewise is outside the POSIX
4624     syntax for both BREs and EREs.
4625    </para>
4626
4627    <para>
4628     Many of the ARE extensions are borrowed from Perl, but some have
4629     been changed to clean them up, and a few Perl extensions are not present.
4630     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
4631     the lack of special treatment for a trailing newline,
4632     the addition of complemented bracket expressions to the things
4633     affected by newline-sensitive matching,
4634     the restrictions on parentheses and back references in lookahead
4635     constraints, and the longest/shortest-match (rather than first-match)
4636     matching semantics.
4637    </para>
4638
4639    <para>
4640     Two significant incompatibilities exist between AREs and the ERE syntax
4641     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
4642
4643     <itemizedlist>
4644      <listitem>
4645       <para>
4646        In AREs, <literal>\</> followed by an alphanumeric character is either
4647        an escape or an error, while in previous releases, it was just another
4648        way of writing the alphanumeric.
4649        This should not be much of a problem because there was no reason to
4650        write such a sequence in earlier releases.
4651       </para>
4652      </listitem>
4653      <listitem>
4654       <para>
4655        In AREs, <literal>\</> remains a special character within
4656        <literal>[]</>, so a literal <literal>\</> within a bracket
4657        expression must be written <literal>\\</>.
4658       </para>
4659      </listitem>
4660     </itemizedlist>
4661
4662     While these differences are unlikely to create a problem for most
4663     applications, you can avoid them if necessary by
4664     setting <varname>regex_flavor</> to <literal>extended</>.
4665    </para>
4666    </sect3>
4667
4668    <sect3 id="posix-basic-regexes">
4669     <title>Basic Regular Expressions</title>
4670
4671    <para>
4672     BREs differ from EREs in several respects.
4673     <literal>|</>, <literal>+</>, and <literal>?</>
4674     are ordinary characters and there is no equivalent
4675     for their functionality.
4676     The delimiters for bounds are
4677     <literal>\{</> and <literal>\}</>,
4678     with <literal>{</> and <literal>}</>
4679     by themselves ordinary characters.
4680     The parentheses for nested subexpressions are
4681     <literal>\(</> and <literal>\)</>,
4682     with <literal>(</> and <literal>)</> by themselves ordinary characters.
4683     <literal>^</> is an ordinary character except at the beginning of the
4684     RE or the beginning of a parenthesized subexpression,
4685     <literal>$</> is an ordinary character except at the end of the
4686     RE or the end of a parenthesized subexpression,
4687     and <literal>*</> is an ordinary character if it appears at the beginning
4688     of the RE or the beginning of a parenthesized subexpression
4689     (after a possible leading <literal>^</>).
4690     Finally, single-digit back references are available, and
4691     <literal>\&lt;</> and <literal>\&gt;</>
4692     are synonyms for
4693     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
4694     respectively; no other escapes are available.
4695    </para>
4696    </sect3>
4697
4698 <!-- end re_syntax.n man page -->
4699
4700   </sect2>
4701  </sect1>
4702
4703
4704   <sect1 id="functions-formatting">
4705    <title>Data Type Formatting Functions</title>
4706
4707    <indexterm>
4708     <primary>formatting</primary>
4709    </indexterm>
4710
4711    <indexterm>
4712     <primary>to_char</primary>
4713    </indexterm>
4714    <indexterm>
4715     <primary>to_date</primary>
4716    </indexterm>
4717    <indexterm>
4718     <primary>to_number</primary>
4719    </indexterm>
4720    <indexterm>
4721     <primary>to_timestamp</primary>
4722    </indexterm>
4723
4724    <para>
4725     The <productname>PostgreSQL</productname> formatting functions
4726     provide a powerful set of tools for converting various data types
4727     (date/time, integer, floating point, numeric) to formatted strings
4728     and for converting from formatted strings to specific data types.
4729     <xref linkend="functions-formatting-table"> lists them.
4730     These functions all follow a common calling convention: the first
4731     argument is the value to be formatted and the second argument is a
4732     template that defines the output or input format.
4733    </para>
4734    <para>
4735     The <function>to_timestamp</function> function can also take a single 
4736     <type>double precision</type> argument to convert from Unix epoch to 
4737     <type>timestamp with time zone</type>.
4738     (<type>Integer</type> Unix epochs are implicitly cast to 
4739     <type>double precision</type>.)
4740    </para>
4741
4742     <table id="functions-formatting-table">
4743      <title>Formatting Functions</title>
4744      <tgroup cols="4">
4745       <thead>
4746        <row>
4747         <entry>Function</entry>
4748         <entry>Return Type</entry>
4749         <entry>Description</entry>
4750         <entry>Example</entry>
4751        </row>
4752       </thead>
4753       <tbody>
4754        <row>
4755         <entry><literal><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</literal></entry>
4756         <entry><type>text</type></entry>
4757         <entry>convert time stamp to string</entry>
4758         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
4759        </row>
4760        <row>
4761         <entry><literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal></entry>
4762         <entry><type>text</type></entry>
4763         <entry>convert interval to string</entry>
4764         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
4765        </row>
4766        <row>
4767         <entry><literal><function>to_char</function>(<type>int</type>, <type>text</type>)</literal></entry>
4768         <entry><type>text</type></entry>
4769         <entry>convert integer to string</entry>
4770         <entry><literal>to_char(125, '999')</literal></entry>
4771        </row>
4772        <row>
4773         <entry><literal><function>to_char</function>(<type>double precision</type>,
4774         <type>text</type>)</literal></entry>
4775         <entry><type>text</type></entry>
4776         <entry>convert real/double precision to string</entry>
4777         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
4778        </row>
4779        <row>
4780         <entry><literal><function>to_char</function>(<type>numeric</type>, <type>text</type>)</literal></entry>
4781         <entry><type>text</type></entry>
4782         <entry>convert numeric to string</entry>
4783         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
4784        </row>
4785        <row>
4786         <entry><literal><function>to_date</function>(<type>text</type>, <type>text</type>)</literal></entry>
4787         <entry><type>date</type></entry>
4788         <entry>convert string to date</entry>
4789         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4790        </row>
4791        <row>
4792         <entry><literal><function>to_number</function>(<type>text</type>, <type>text</type>)</literal></entry>
4793         <entry><type>numeric</type></entry>
4794         <entry>convert string to numeric</entry>
4795         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
4796        </row>
4797        <row>
4798         <entry><literal><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</literal></entry>
4799         <entry><type>timestamp with time zone</type></entry>
4800         <entry>convert string to time stamp</entry>
4801         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4802        </row>
4803        <row>
4804         <entry><literal><function>to_timestamp</function>(<type>double precision</type>)</literal></entry>
4805         <entry><type>timestamp with time zone</type></entry>
4806         <entry>convert UNIX epoch to time stamp</entry>
4807         <entry><literal>to_timestamp(200120400)</literal></entry>
4808        </row>
4809       </tbody>
4810      </tgroup>
4811     </table>
4812
4813    <para>
4814     In an output template string (for <function>to_char</>), there are certain patterns that are
4815     recognized and replaced with appropriately-formatted data from the value
4816     to be formatted.  Any text that is not a template pattern is simply
4817     copied verbatim.  Similarly, in an input template string (for anything but <function>to_char</>), template patterns
4818     identify the parts of the input data string to be looked at and the
4819     values to be found there.
4820    </para>
4821
4822   <para>
4823    <xref linkend="functions-formatting-datetime-table"> shows the
4824    template patterns available for formatting date and time values.
4825   </para>
4826
4827     <table id="functions-formatting-datetime-table">
4828      <title>Template Patterns for Date/Time Formatting</title>
4829      <tgroup cols="2">
4830       <thead>
4831        <row>
4832         <entry>Pattern</entry>
4833         <entry>Description</entry>
4834        </row>
4835       </thead>
4836       <tbody>
4837        <row>
4838         <entry><literal>HH</literal></entry>
4839         <entry>hour of day (01-12)</entry>
4840        </row>
4841        <row>
4842         <entry><literal>HH12</literal></entry>
4843         <entry>hour of day (01-12)</entry>
4844        </row>       
4845        <row>
4846         <entry><literal>HH24</literal></entry>
4847         <entry>hour of day (00-23)</entry>
4848        </row>       
4849        <row>
4850         <entry><literal>MI</literal></entry>
4851         <entry>minute (00-59)</entry>
4852        </row>   
4853        <row>
4854         <entry><literal>SS</literal></entry>
4855         <entry>second (00-59)</entry>
4856        </row>
4857        <row>
4858         <entry><literal>MS</literal></entry>
4859         <entry>millisecond (000-999)</entry>
4860        </row>
4861        <row>
4862         <entry><literal>US</literal></entry>
4863         <entry>microsecond (000000-999999)</entry>
4864        </row>
4865        <row>
4866         <entry><literal>SSSS</literal></entry>
4867         <entry>seconds past midnight (0-86399)</entry>
4868        </row>
4869        <row>
4870         <entry><literal>AM</literal> or <literal>A.M.</literal> or
4871         <literal>PM</literal> or <literal>P.M.</literal></entry>
4872         <entry>meridian indicator (uppercase)</entry>
4873        </row>
4874        <row>
4875         <entry><literal>am</literal> or <literal>a.m.</literal> or
4876         <literal>pm</literal> or <literal>p.m.</literal></entry>
4877         <entry>meridian indicator (lowercase)</entry>
4878        </row>
4879        <row>
4880         <entry><literal>Y,YYY</literal></entry>
4881         <entry>year (4 and more digits) with comma</entry>
4882        </row>
4883        <row>
4884         <entry><literal>YYYY</literal></entry>
4885         <entry>year (4 and more digits)</entry>
4886        </row>
4887        <row>
4888         <entry><literal>YYY</literal></entry>
4889         <entry>last 3 digits of year</entry>
4890        </row>
4891        <row>
4892         <entry><literal>YY</literal></entry>
4893         <entry>last 2 digits of year</entry>
4894        </row>
4895        <row>
4896         <entry><literal>Y</literal></entry>
4897         <entry>last digit of year</entry>
4898        </row>
4899        <row>
4900         <entry><literal>IYYY</literal></entry>
4901         <entry>ISO year (4 and more digits)</entry>
4902        </row>
4903        <row>
4904         <entry><literal>IYY</literal></entry>
4905         <entry>last 3 digits of ISO year</entry>
4906        </row>
4907        <row>
4908         <entry><literal>IY</literal></entry>
4909         <entry>last 2 digits of ISO year</entry>
4910        </row>
4911        <row>
4912         <entry><literal>I</literal></entry>
4913         <entry>last digit of ISO year</entry>
4914        </row>
4915        <row>
4916         <entry><literal>BC</literal> or <literal>B.C.</literal> or
4917         <literal>AD</literal> or <literal>A.D.</literal></entry>
4918         <entry>era indicator (uppercase)</entry>
4919        </row>
4920        <row>
4921         <entry><literal>bc</literal> or <literal>b.c.</literal> or
4922         <literal>ad</literal> or <literal>a.d.</literal></entry>
4923         <entry>era indicator (lowercase)</entry>
4924        </row>
4925        <row>
4926         <entry><literal>MONTH</literal></entry>
4927         <entry>full uppercase month name (blank-padded to 9 chars)</entry>
4928        </row>
4929        <row>
4930         <entry><literal>Month</literal></entry>
4931         <entry>full mixed-case month name (blank-padded to 9 chars)</entry>
4932        </row>
4933        <row>
4934         <entry><literal>month</literal></entry>
4935         <entry>full lowercase month name (blank-padded to 9 chars)</entry>
4936        </row>
4937        <row>
4938         <entry><literal>MON</literal></entry>
4939         <entry>abbreviated uppercase month name (3 chars in English, localized lengths vary)</entry>
4940        </row>
4941        <row>
4942         <entry><literal>Mon</literal></entry>
4943         <entry>abbreviated mixed-case month name (3 chars in English, localized lengths vary)</entry>
4944        </row>
4945        <row>
4946         <entry><literal>mon</literal></entry>
4947         <entry>abbreviated lowercase month name (3 chars in English, localized lengths vary)</entry>
4948        </row>
4949        <row>
4950         <entry><literal>MM</literal></entry>
4951         <entry>month number (01-12)</entry>
4952        </row>
4953        <row>
4954         <entry><literal>DAY</literal></entry>
4955         <entry>full uppercase day name (blank-padded to 9 chars)</entry>
4956        </row>
4957        <row>
4958         <entry><literal>Day</literal></entry>
4959         <entry>full mixed-case day name (blank-padded to 9 chars)</entry>
4960        </row>
4961        <row>
4962         <entry><literal>day</literal></entry>
4963         <entry>full lowercase day name (blank-padded to 9 chars)</entry>
4964        </row>
4965        <row>
4966         <entry><literal>DY</literal></entry>
4967         <entry>abbreviated uppercase day name (3 chars in English, localized lengths vary)</entry>
4968        </row>
4969        <row>
4970         <entry><literal>Dy</literal></entry>
4971         <entry>abbreviated mixed-case day name (3 chars in English, localized lengths vary)</entry>
4972        </row>
4973        <row>
4974         <entry><literal>dy</literal></entry>
4975         <entry>abbreviated lowercase day name (3 chars in English, localized lengths vary)</entry>
4976        </row>
4977        <row>
4978         <entry><literal>DDD</literal></entry>
4979         <entry>day of year (001-366)</entry>
4980        </row>
4981        <row>
4982         <entry><literal>IDDD</literal></entry>
4983         <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
4984        </row>
4985        <row>
4986         <entry><literal>DD</literal></entry>
4987         <entry>day of month (01-31)</entry>
4988        </row>
4989        <row>
4990         <entry><literal>D</literal></entry>
4991         <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
4992        </row>
4993        <row>
4994         <entry><literal>ID</literal></entry>
4995         <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
4996        </row>
4997        <row>
4998         <entry><literal>W</literal></entry>
4999         <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
5000        </row> 
5001        <row>
5002         <entry><literal>WW</literal></entry>
5003         <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
5004        </row>
5005        <row>
5006         <entry><literal>IW</literal></entry>
5007         <entry>ISO week number of year (1 - 53; the first Thursday of the new year is in week 1.)</entry>
5008        </row>
5009        <row>
5010         <entry><literal>CC</literal></entry>
5011         <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
5012        </row>
5013        <row>
5014         <entry><literal>J</literal></entry>
5015         <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
5016        </row>
5017        <row>
5018         <entry><literal>Q</literal></entry>
5019         <entry>quarter</entry>
5020        </row>
5021        <row>
5022         <entry><literal>RM</literal></entry>
5023         <entry>month in Roman numerals (I-XII; I=January) (uppercase)</entry>
5024        </row>
5025        <row>
5026         <entry><literal>rm</literal></entry>
5027         <entry>month in Roman numerals (i-xii; i=January) (lowercase)</entry>
5028        </row>
5029        <row>
5030         <entry><literal>TZ</literal></entry>
5031         <entry>time-zone name (uppercase)</entry>
5032        </row>
5033        <row>
5034         <entry><literal>tz</literal></entry>
5035         <entry>time-zone name (lowercase)</entry>
5036        </row>
5037       </tbody>
5038      </tgroup>
5039     </table>
5040
5041    <para>
5042     Certain modifiers can be applied to any template pattern to alter its
5043     behavior.  For example, <literal>FMMonth</literal>
5044     is the <literal>Month</literal> pattern with the
5045     <literal>FM</literal> modifier.
5046     <xref linkend="functions-formatting-datetimemod-table"> shows the
5047     modifier patterns for date/time formatting.
5048    </para>
5049
5050     <table id="functions-formatting-datetimemod-table">
5051      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5052      <tgroup cols="3">
5053       <thead>
5054        <row>
5055         <entry>Modifier</entry>
5056         <entry>Description</entry>
5057         <entry>Example</entry>
5058        </row>
5059       </thead>
5060       <tbody>
5061        <row>
5062         <entry><literal>FM</literal> prefix</entry>
5063         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5064         <entry><literal>FMMonth</literal></entry>
5065        </row>
5066        <row>
5067         <entry><literal>TH</literal> suffix</entry>
5068         <entry>uppercase ordinal number suffix</entry>
5069         <entry><literal>DDTH</literal></entry>
5070        </row>   
5071        <row>
5072         <entry><literal>th</literal> suffix</entry>
5073         <entry>lowercase ordinal number suffix</entry>
5074         <entry><literal>DDth</literal></entry>
5075        </row>
5076        <row>
5077         <entry><literal>FX</literal> prefix</entry>
5078         <entry>fixed format global option (see usage notes)</entry>
5079         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5080        </row>   
5081        <row>
5082         <entry><literal>TM</literal> prefix</entry>
5083         <entry>translation mode (print localized day and month names based on
5084          <xref linkend="guc-lc-time">)</entry>
5085         <entry><literal>TMMonth</literal></entry>
5086        </row>       
5087        <row>
5088         <entry><literal>SP</literal> suffix</entry>
5089         <entry>spell mode (not yet implemented)</entry>
5090         <entry><literal>DDSP</literal></entry>
5091        </row>       
5092       </tbody>
5093      </tgroup>
5094     </table>
5095
5096    <para>
5097     Usage notes for date/time formatting:
5098
5099     <itemizedlist>
5100      <listitem>
5101       <para>
5102        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5103        that would otherwise be added to make the output of a pattern be
5104        fixed-width.
5105       </para>
5106      </listitem>
5107
5108      <listitem>
5109       <para>
5110        <literal>TM</literal> does not include trailing blanks.
5111       </para>
5112      </listitem>
5113
5114      <listitem>
5115       <para>
5116        <function>to_timestamp</function> and <function>to_date</function>
5117        skip multiple blank spaces in the input string if the <literal>FX</literal> option 
5118        is not used. <literal>FX</literal> must be specified as the first item
5119        in the template.  For example 
5120        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> is correct, but
5121        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error,
5122        because <function>to_timestamp</function> expects one space only.
5123       </para>
5124      </listitem>
5125
5126      <listitem>
5127       <para>
5128        Ordinary text is allowed in <function>to_char</function>
5129        templates and will be output literally.  You can put a substring
5130        in double quotes to force it to be interpreted as literal text
5131        even if it contains pattern key words.  For example, in
5132        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5133        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5134        will not be.
5135       </para>
5136      </listitem>
5137
5138      <listitem>
5139       <para>
5140        If you want to have a double quote in the output you must
5141        precede it with a backslash, for example <literal>E'\\"YYYY
5142        Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
5143        (Two backslashes are necessary because the backslash already
5144        has a special meaning when using the escape string syntax.)
5145       </para>
5146      </listitem>
5147
5148      <listitem>
5149       <para>
5150        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5151        <type>date</type> has a restriction if you use a year with more than 4 digits. You must
5152        use some non-digit character or template after <literal>YYYY</literal>,
5153        otherwise the year is always interpreted as 4 digits. For example
5154        (with the year 20000):
5155        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
5156        interpreted as a 4-digit year; instead use a non-digit 
5157        separator after the year, like
5158        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5159        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5160       </para>
5161      </listitem>
5162
5163      <listitem>
5164       <para>
5165        In conversions from string to <type>timestamp</type> or
5166        <type>date</type>, the <literal>CC</literal> field is ignored if there
5167        is a <literal>YYY</literal>, <literal>YYYY</literal> or
5168        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5169        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5170        as <literal>(CC-1)*100+YY</literal>.
5171       </para>
5172      </listitem>
5173
5174      <listitem>
5175       <para>
5176        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:
5177        <itemizedlist>
5178         <listitem>
5179          <para>
5180           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).
5181          </para>
5182         </listitem>
5183         <listitem>
5184          <para>
5185           Year and day of year, for example <literal>to_date('2006-291', 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5186          </para>
5187         </listitem>
5188        </itemizedlist>
5189       </para>
5190       <para>
5191        Attempting to construct a date using a mixture of ISO week and
5192        Gregorian date fields is nonsensical, and will cause an error.  In the
5193        context of an ISO year, the concept of a <quote>month</> or <quote>day
5194        of month</> has no meaning.  In the context of a Gregorian year, the
5195        ISO week has no meaning.  Users should take care to keep Gregorian and
5196        ISO date specifications separate.
5197       </para>
5198      </listitem>
5199
5200      <listitem>
5201       <para>
5202        Millisecond (<literal>MS</literal>) and microsecond (<literal>US</literal>)
5203        values in a conversion from string to <type>timestamp</type> are used as part of the
5204        seconds after the decimal point. For example 
5205        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5206        but 300, because the conversion counts it as 12 + 0.3 seconds.
5207        This means for the format <literal>SS:MS</literal>, the input values
5208        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5209        same number of milliseconds. To get three milliseconds, one must use
5210        <literal>12:003</literal>, which the conversion counts as
5211        12 + 0.003 = 12.003 seconds.
5212       </para>
5213
5214       <para>
5215        Here is a more 
5216        complex example: 
5217        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5218        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5219        1230 microseconds = 2.021230 seconds. 
5220       </para>
5221      </listitem>
5222
5223      <listitem>
5224       <para>
5225         <function>to_char(..., 'ID')</function>'s day of the week numbering
5226         matches the <function>extract('isodow', ...)</function> function, but
5227         <function>to_char(..., 'D')</function>'s does not match
5228         <function>extract('dow', ...)</function>'s day numbering.
5229       </para>
5230      </listitem>
5231
5232      <listitem>
5233       <para><function>to_char(interval)</function> formats <literal>HH</> and 
5234         <literal>HH12</> as hours in a single day, while <literal>HH24</>
5235         can output hours exceeding a single day, e.g. &gt;24.
5236       </para>
5237      </listitem>
5238
5239     </itemizedlist>
5240    </para>
5241
5242   <para>
5243    <xref linkend="functions-formatting-numeric-table"> shows the
5244    template patterns available for formatting numeric values.
5245   </para>
5246
5247     <table id="functions-formatting-numeric-table">
5248      <title>Template Patterns for Numeric Formatting</title>
5249      <tgroup cols="2">
5250       <thead>
5251        <row>
5252         <entry>Pattern</entry>
5253         <entry>Description</entry>
5254        </row>
5255       </thead>
5256       <tbody>
5257        <row>
5258         <entry><literal>9</literal></entry>
5259         <entry>value with the specified number of digits</entry>
5260        </row>
5261        <row>
5262         <entry><literal>0</literal></entry>
5263         <entry>value with leading zeros</entry>
5264        </row>
5265        <row>
5266         <entry><literal>.</literal> (period)</entry>
5267         <entry>decimal point</entry>
5268        </row>       
5269        <row>
5270         <entry><literal>,</literal> (comma)</entry>
5271         <entry>group (thousand) separator</entry>
5272        </row>
5273        <row>
5274         <entry><literal>PR</literal></entry>
5275         <entry>negative value in angle brackets</entry>
5276        </row>
5277        <row>
5278         <entry><literal>S</literal></entry>
5279         <entry>sign anchored to number (uses locale)</entry>
5280        </row>
5281        <row>
5282         <entry><literal>L</literal></entry>
5283         <entry>currency symbol (uses locale)</entry>
5284        </row>
5285        <row>
5286         <entry><literal>D</literal></entry>
5287         <entry>decimal point (uses locale)</entry>
5288        </row>
5289        <row>
5290         <entry><literal>G</literal></entry>
5291         <entry>group separator (uses locale)</entry>
5292        </row>
5293        <row>
5294         <entry><literal>MI</literal></entry>
5295         <entry>minus sign in specified position (if number &lt; 0)</entry>
5296        </row>
5297        <row>
5298         <entry><literal>PL</literal></entry>
5299         <entry>plus sign in specified position (if number &gt; 0)</entry>
5300        </row>
5301        <row>
5302         <entry><literal>SG</literal></entry>
5303         <entry>plus/minus sign in specified position</entry>
5304        </row>
5305        <row>
5306         <entry><literal>RN</literal></entry>
5307         <entry>roman numeral (input between 1 and 3999)</entry>
5308        </row>
5309        <row>
5310         <entry><literal>TH</literal> or <literal>th</literal></entry>
5311         <entry>ordinal number suffix</entry>
5312        </row>
5313        <row>
5314         <entry><literal>V</literal></entry>
5315         <entry>shift specified number of digits (see notes)</entry>
5316        </row>
5317        <row>
5318         <entry><literal>EEEE</literal></entry>
5319         <entry>scientific notation (not implemented yet)</entry>
5320        </row>
5321       </tbody>
5322      </tgroup>
5323     </table>
5324
5325    <para>
5326     Usage notes for numeric formatting:
5327
5328     <itemizedlist>
5329      <listitem>
5330       <para>
5331        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5332        <literal>MI</literal> is not anchored to
5333        the number; for example,
5334        <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>,
5335        but <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>.
5336        The Oracle implementation does not allow the use of
5337        <literal>MI</literal> ahead of <literal>9</literal>, but rather
5338        requires that <literal>9</literal> precede
5339        <literal>MI</literal>.
5340       </para>
5341      </listitem>
5342
5343      <listitem>
5344       <para>
5345        <literal>9</literal> results in a value with the same number of 
5346        digits as there are <literal>9</literal>s. If a digit is
5347        not available it outputs a space.
5348       </para>
5349      </listitem>
5350
5351      <listitem>
5352       <para>
5353        <literal>TH</literal> does not convert values less than zero
5354        and does not convert fractional numbers.
5355       </para>
5356      </listitem>
5357
5358      <listitem>
5359       <para>
5360        <literal>PL</literal>, <literal>SG</literal>, and
5361        <literal>TH</literal> are <productname>PostgreSQL</productname>
5362        extensions. 
5363       </para>
5364      </listitem>
5365
5366      <listitem>
5367       <para>
5368        <literal>V</literal> effectively
5369        multiplies the input values by
5370        <literal>10^<replaceable>n</replaceable></literal>, where
5371        <replaceable>n</replaceable> is the number of digits following
5372        <literal>V</literal>. 
5373        <function>to_char</function> does not support the use of
5374        <literal>V</literal> combined with a decimal point.
5375        (E.g., <literal>99.9V99</literal> is not allowed.)
5376       </para>
5377      </listitem>
5378     </itemizedlist>
5379    </para>   
5380
5381    <para>
5382     Certain modifiers can be applied to any template pattern to alter its
5383     behavior.  For example, <literal>FM9999</literal>
5384     is the <literal>9999</literal> pattern with the
5385     <literal>FM</literal> modifier.
5386     <xref linkend="functions-formatting-numericmod-table"> shows the
5387     modifier patterns for numeric formatting.
5388    </para>
5389
5390     <table id="functions-formatting-numericmod-table">
5391      <title>Template Pattern Modifiers for Numeric Formatting</title>
5392      <tgroup cols="3">
5393       <thead>
5394        <row>
5395         <entry>Modifier</entry>
5396         <entry>Description</entry>
5397         <entry>Example</entry>
5398        </row>
5399       </thead>
5400       <tbody>
5401        <row>
5402         <entry><literal>FM</literal> prefix</entry>
5403         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5404         <entry><literal>FM9999</literal></entry>
5405        </row>
5406        <row>
5407         <entry><literal>TH</literal> suffix</entry>
5408         <entry>uppercase ordinal number suffix</entry>
5409         <entry><literal>999TH</literal></entry>
5410        </row>   
5411        <row>
5412         <entry><literal>th</literal> suffix</entry>
5413         <entry>lowercase ordinal number suffix</entry>
5414         <entry><literal>999th</literal></entry>
5415        </row>
5416       </tbody>
5417      </tgroup>
5418     </table>
5419
5420   <para>
5421    <xref linkend="functions-formatting-examples-table"> shows some
5422    examples of the use of the <function>to_char</function> function.
5423   </para>
5424
5425     <table id="functions-formatting-examples-table">
5426      <title><function>to_char</function> Examples</title>
5427      <tgroup cols="2">
5428       <thead>
5429        <row>
5430         <entry>Expression</entry>
5431         <entry>Result</entry>
5432        </row>
5433       </thead>
5434       <tbody>
5435        <row>
5436         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5437         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
5438        </row>
5439        <row>
5440         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5441         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
5442        </row>          
5443        <row>
5444         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5445         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
5446        </row>
5447        <row>
5448         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5449         <entry><literal>'-.1'</literal></entry>
5450        </row>
5451        <row>
5452         <entry><literal>to_char(0.1, '0.9')</literal></entry>
5453         <entry><literal>'&nbsp;0.1'</literal></entry>
5454        </row>
5455        <row>
5456         <entry><literal>to_char(12, '9990999.9')</literal></entry>
5457         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
5458        </row>
5459        <row>
5460         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5461         <entry><literal>'0012.'</literal></entry>
5462        </row>
5463        <row>
5464         <entry><literal>to_char(485, '999')</literal></entry>
5465         <entry><literal>'&nbsp;485'</literal></entry>
5466        </row>
5467        <row>
5468         <entry><literal>to_char(-485, '999')</literal></entry>
5469         <entry><literal>'-485'</literal></entry>
5470        </row>
5471        <row>
5472         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
5473         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
5474        </row>
5475        <row>
5476         <entry><literal>to_char(1485, '9,999')</literal></entry>
5477         <entry><literal>'&nbsp;1,485'</literal></entry>
5478        </row>
5479        <row>
5480         <entry><literal>to_char(1485, '9G999')</literal></entry>
5481         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
5482        </row>
5483        <row>
5484         <entry><literal>to_char(148.5, '999.999')</literal></entry>
5485         <entry><literal>'&nbsp;148.500'</literal></entry>
5486        </row>
5487        <row>
5488         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5489         <entry><literal>'148.5'</literal></entry>
5490        </row>
5491        <row>
5492         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5493         <entry><literal>'148.500'</literal></entry>
5494        </row>
5495        <row>
5496         <entry><literal>to_char(148.5, '999D999')</literal></entry>
5497         <entry><literal>'&nbsp;148,500'</literal></entry>        
5498        </row>
5499        <row>
5500         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5501         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
5502        </row>
5503        <row>
5504         <entry><literal>to_char(-485, '999S')</literal></entry>
5505         <entry><literal>'485-'</literal></entry>
5506        </row>
5507        <row>            
5508         <entry><literal>to_char(-485, '999MI')</literal></entry>
5509         <entry><literal>'485-'</literal></entry>        
5510        </row>
5511        <row>
5512         <entry><literal>to_char(485, '999MI')</literal></entry>
5513         <entry><literal>'485&nbsp;'</literal></entry>           
5514        </row>
5515        <row>
5516         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5517         <entry><literal>'485'</literal></entry>         
5518        </row>
5519        <row>
5520         <entry><literal>to_char(485, 'PL999')</literal></entry>
5521         <entry><literal>'+485'</literal></entry>        
5522        </row>
5523        <row>            
5524         <entry><literal>to_char(485, 'SG999')</literal></entry>
5525         <entry><literal>'+485'</literal></entry>        
5526        </row>
5527        <row>
5528         <entry><literal>to_char(-485, 'SG999')</literal></entry>
5529         <entry><literal>'-485'</literal></entry>        
5530        </row>
5531        <row>
5532         <entry><literal>to_char(-485, '9SG99')</literal></entry>
5533         <entry><literal>'4-85'</literal></entry>        
5534        </row>
5535        <row>
5536         <entry><literal>to_char(-485, '999PR')</literal></entry>
5537         <entry><literal>'&lt;485&gt;'</literal></entry>         
5538        </row>
5539        <row>
5540         <entry><literal>to_char(485, 'L999')</literal></entry>
5541         <entry><literal>'DM&nbsp;485</literal></entry>   
5542        </row>
5543        <row>
5544         <entry><literal>to_char(485, 'RN')</literal></entry>            
5545         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
5546        </row>
5547        <row>
5548         <entry><literal>to_char(485, 'FMRN')</literal></entry>  
5549         <entry><literal>'CDLXXXV'</literal></entry>
5550        </row>
5551        <row>
5552         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5553         <entry><literal>'V'</literal></entry>           
5554        </row>
5555        <row>
5556         <entry><literal>to_char(482, '999th')</literal></entry>
5557         <entry><literal>'&nbsp;482nd'</literal></entry>                         
5558        </row>
5559        <row>
5560         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
5561         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
5562        </row>
5563        <row>
5564         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
5565         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
5566        </row>
5567        <row>
5568         <entry><literal>to_char(12, '99V999')</literal></entry>         
5569         <entry><literal>'&nbsp;12000'</literal></entry>
5570        </row>
5571        <row>
5572         <entry><literal>to_char(12.4, '99V999')</literal></entry>
5573         <entry><literal>'&nbsp;12400'</literal></entry>
5574        </row>
5575        <row>            
5576         <entry><literal>to_char(12.45, '99V9')</literal></entry>
5577         <entry><literal>'&nbsp;125'</literal></entry>
5578        </row>
5579       </tbody>
5580      </tgroup>
5581     </table>
5582
5583   </sect1>
5584
5585
5586   <sect1 id="functions-datetime">
5587    <title>Date/Time Functions and Operators</title>
5588
5589   <para>
5590    <xref linkend="functions-datetime-table"> shows the available
5591    functions for date/time value processing, with details appearing in
5592    the following subsections.  <xref
5593    linkend="operators-datetime-table"> illustrates the behaviors of
5594    the basic arithmetic operators (<literal>+</literal>,
5595    <literal>*</literal>, etc.).  For formatting functions, refer to
5596    <xref linkend="functions-formatting">.  You should be familiar with
5597    the background information on date/time data types from <xref
5598    linkend="datatype-datetime">.
5599   </para>
5600
5601   <para>
5602    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
5603    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
5604    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
5605    For brevity, these variants are not shown separately.  Also, the
5606    <literal>+</> and <literal>*</> operators come in commutative pairs (for
5607    example both date + integer and integer + date); we show only one of each
5608    such pair.
5609   </para>
5610
5611     <table id="operators-datetime-table">
5612      <title>Date/Time Operators</title>
5613
5614      <tgroup cols="3">
5615       <thead>
5616        <row>
5617         <entry>Operator</entry>
5618         <entry>Example</entry>
5619         <entry>Result</entry>
5620        </row>
5621       </thead>
5622
5623       <tbody>
5624        <row>
5625         <entry> <literal>+</literal> </entry>
5626         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
5627         <entry><literal>date '2001-10-05'</literal></entry>
5628        </row>
5629
5630        <row>
5631         <entry> <literal>+</literal> </entry>
5632         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
5633         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
5634        </row>
5635
5636        <row>
5637         <entry> <literal>+</literal> </entry>
5638         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
5639         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
5640        </row>
5641
5642        <row>
5643         <entry> <literal>+</literal> </entry>
5644         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
5645         <entry><literal>interval '1 day 01:00:00'</literal></entry>
5646        </row>
5647
5648        <row>
5649         <entry> <literal>+</literal> </entry>
5650         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
5651         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
5652        </row>
5653
5654        <row>
5655         <entry> <literal>+</literal> </entry>
5656         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
5657         <entry><literal>time '04:00:00'</literal></entry>
5658        </row>
5659
5660        <row>
5661         <entry> <literal>-</literal> </entry>
5662         <entry><literal>- interval '23 hours'</literal></entry>
5663         <entry><literal>interval '-23:00:00'</literal></entry>
5664        </row>
5665
5666        <row>
5667         <entry> <literal>-</literal> </entry>
5668         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
5669         <entry><literal>integer '3'</literal></entry>
5670        </row>
5671
5672        <row>
5673         <entry> <literal>-</literal> </entry>
5674         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
5675         <entry><literal>date '2001-09-24'</literal></entry>
5676        </row>
5677
5678        <row>
5679         <entry> <literal>-</literal> </entry>
5680         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
5681         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
5682        </row>
5683
5684        <row>
5685         <entry> <literal>-</literal> </entry>
5686         <entry><literal>time '05:00' - time '03:00'</literal></entry>
5687         <entry><literal>interval '02:00:00'</literal></entry>
5688        </row>
5689
5690        <row>
5691         <entry> <literal>-</literal> </entry>
5692         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
5693         <entry><literal>time '03:00:00'</literal></entry>
5694        </row>
5695
5696        <row>
5697         <entry> <literal>-</literal> </entry>
5698         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
5699         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
5700        </row>
5701
5702        <row>
5703         <entry> <literal>-</literal> </entry>
5704         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
5705         <entry><literal>interval '1 day -01:00:00'</literal></entry>
5706        </row>
5707
5708        <row>
5709         <entry> <literal>-</literal> </entry>
5710         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
5711         <entry><literal>interval '1 day 15:00:00'</literal></entry>
5712        </row>
5713
5714        <row>
5715         <entry> <literal>*</literal> </entry>
5716         <entry><literal>900 * interval '1 second'</literal></entry>
5717         <entry><literal>interval '00:15:00'</literal></entry>
5718        </row>
5719
5720        <row>
5721         <entry> <literal>*</literal> </entry>
5722         <entry><literal>21 * interval '1 day'</literal></entry>
5723         <entry><literal>interval '21 days'</literal></entry>
5724        </row>
5725
5726        <row>
5727         <entry> <literal>*</literal> </entry>
5728         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
5729         <entry><literal>interval '03:30:00'</literal></entry>
5730        </row>
5731
5732        <row>
5733         <entry> <literal>/</literal> </entry>
5734         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
5735         <entry><literal>interval '00:40:00'</literal></entry>
5736        </row>
5737       </tbody>
5738      </tgroup>
5739     </table>
5740
5741    <indexterm>
5742     <primary>age</primary>
5743    </indexterm>
5744    <indexterm>
5745     <primary>clock_timestamp</primary>
5746    </indexterm>
5747    <indexterm>
5748     <primary>current_date</primary>
5749    </indexterm>
5750    <indexterm>
5751     <primary>current_time</primary>
5752    </indexterm>
5753    <indexterm>
5754     <primary>current_timestamp</primary>
5755    </indexterm>
5756    <indexterm>
5757     <primary>date_part</primary>
5758    </indexterm>
5759    <indexterm>
5760     <primary>date_trunc</primary>
5761    </indexterm>
5762    <indexterm>
5763     <primary>extract</primary>
5764    </indexterm>
5765    <indexterm>
5766     <primary>isfinite</primary>
5767    </indexterm>
5768    <indexterm>
5769     <primary>justify_days</primary>
5770    </indexterm>
5771    <indexterm>
5772     <primary>justify_hours</primary>
5773    </indexterm>
5774    <indexterm>
5775     <primary>justify_interval</primary>
5776    </indexterm>
5777    <indexterm>
5778     <primary>localtime</primary>
5779    </indexterm>
5780    <indexterm>
5781     <primary>localtimestamp</primary>
5782    </indexterm>
5783    <indexterm>
5784     <primary>now</primary>
5785    </indexterm>
5786    <indexterm>
5787     <primary>statement_timestamp</primary>
5788    </indexterm>
5789    <indexterm>
5790     <primary>timeofday</primary>
5791    </indexterm>
5792    <indexterm>
5793     <primary>transaction_timestamp</primary>
5794    </indexterm>
5795
5796     <table id="functions-datetime-table">
5797      <title>Date/Time Functions</title>
5798      <tgroup cols="5">
5799       <thead>
5800        <row>
5801         <entry>Function</entry>
5802         <entry>Return Type</entry>
5803         <entry>Description</entry>
5804         <entry>Example</entry>
5805         <entry>Result</entry>
5806        </row>
5807       </thead>
5808
5809       <tbody>
5810        <row>
5811         <entry><literal><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</literal></entry>
5812         <entry><type>interval</type></entry>
5813         <entry>Subtract arguments, producing a <quote>symbolic</> result that
5814         uses years and months</entry>
5815         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
5816         <entry><literal>43 years 9 mons 27 days</literal></entry>
5817        </row>
5818
5819        <row>
5820         <entry><literal><function>age</function>(<type>timestamp</type>)</literal></entry>
5821         <entry><type>interval</type></entry>
5822         <entry>Subtract from <function>current_date</function></entry>
5823         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
5824         <entry><literal>43 years 8 mons 3 days</literal></entry>
5825        </row>
5826
5827        <row>
5828         <entry><literal><function>clock_timestamp</function>()</literal></entry>
5829         <entry><type>timestamp with time zone</type></entry>
5830         <entry>Current date and time (changes during statement execution);
5831          see <xref linkend="functions-datetime-current">
5832         </entry>
5833         <entry></entry>
5834         <entry></entry>
5835        </row>
5836
5837        <row>
5838         <entry><literal><function>current_date</function></literal></entry>
5839         <entry><type>date</type></entry>
5840         <entry>Current date;
5841          see <xref linkend="functions-datetime-current">
5842         </entry>
5843         <entry></entry>
5844         <entry></entry>
5845        </row>
5846
5847        <row>
5848         <entry><literal><function>current_time</function></literal></entry>
5849         <entry><type>time with time zone</type></entry>
5850         <entry>Current time of day;
5851          see <xref linkend="functions-datetime-current">
5852         </entry>
5853         <entry></entry>
5854         <entry></entry>
5855        </row>
5856
5857        <row>
5858         <entry><literal><function>current_timestamp</function></literal></entry>
5859         <entry><type>timestamp with time zone</type></entry>
5860         <entry>Current date and time (start of current transaction);
5861          see <xref linkend="functions-datetime-current">
5862         </entry>
5863         <entry></entry>
5864         <entry></entry>
5865        </row>
5866
5867        <row>
5868         <entry><literal><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5869         <entry><type>double precision</type></entry>
5870         <entry>Get subfield (equivalent to <function>extract</function>);
5871          see <xref linkend="functions-datetime-extract">
5872         </entry>
5873         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5874         <entry><literal>20</literal></entry>
5875        </row>
5876
5877        <row>
5878         <entry><literal><function>date_part</function>(<type>text</type>, <type>interval</type>)</literal></entry>
5879         <entry><type>double precision</type></entry>
5880         <entry>Get subfield (equivalent to
5881          <function>extract</function>); see <xref linkend="functions-datetime-extract">
5882         </entry>
5883         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
5884         <entry><literal>3</literal></entry>
5885        </row>
5886
5887        <row>
5888         <entry><literal><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5889         <entry><type>timestamp</type></entry>
5890         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
5891         </entry>
5892         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5893         <entry><literal>2001-02-16 20:00:00</literal></entry>
5894        </row>
5895
5896        <row>
5897         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5898          <type>timestamp</type>)</literal></entry>
5899         <entry><type>double precision</type></entry>
5900         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5901         </entry>
5902         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
5903         <entry><literal>20</literal></entry>
5904        </row>
5905
5906        <row>
5907         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5908          <type>interval</type>)</literal></entry>
5909         <entry><type>double precision</type></entry>
5910         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5911         </entry>
5912         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
5913         <entry><literal>3</literal></entry>
5914        </row>
5915
5916        <row>
5917         <entry><literal><function>isfinite</function>(<type>date</type>)</literal></entry>
5918         <entry><type>boolean</type></entry>
5919         <entry>Test for finite date (not +/-infinity)</entry>
5920         <entry><literal>isfinite(date '2001-02-16')</literal></entry>
5921         <entry><literal>true</literal></entry>
5922        </row>
5923
5924        <row>
5925         <entry><literal><function>isfinite</function>(<type>timestamp</type>)</literal></entry>
5926         <entry><type>boolean</type></entry>
5927         <entry>Test for finite time stamp (not +/-infinity)</entry>
5928         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
5929         <entry><literal>true</literal></entry>
5930        </row>
5931
5932        <row>
5933         <entry><literal><function>isfinite</function>(<type>interval</type>)</literal></entry>
5934         <entry><type>boolean</type></entry>
5935         <entry>Test for finite interval</entry>
5936         <entry><literal>isfinite(interval '4 hours')</literal></entry>
5937         <entry><literal>true</literal></entry>
5938        </row>
5939
5940        <row>
5941         <entry><literal><function>justify_days</function>(<type>interval</type>)</literal></entry>
5942         <entry><type>interval</type></entry>
5943         <entry>Adjust interval so 30-day time periods are represented as months</entry>
5944         <entry><literal>justify_days(interval '30 days')</literal></entry>
5945         <entry><literal>1 month</literal></entry>
5946        </row>
5947
5948        <row>
5949         <entry><literal><function>justify_hours</function>(<type>interval</type>)</literal></entry>
5950         <entry><type>interval</type></entry>
5951         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
5952         <entry><literal>justify_hours(interval '24 hours')</literal></entry>
5953         <entry><literal>1 day</literal></entry>
5954        </row>
5955
5956        <row>
5957         <entry><literal><function>justify_interval</function>(<type>interval</type>)</literal></entry>
5958         <entry><type>interval</type></entry>
5959         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
5960         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
5961         <entry><literal>29 days 23:00:00</literal></entry>
5962        </row>
5963
5964        <row>
5965         <entry><literal><function>localtime</function></literal></entry>
5966         <entry><type>time</type></entry>
5967         <entry>Current time of day;
5968          see <xref linkend="functions-datetime-current">
5969         </entry>
5970         <entry></entry>
5971         <entry></entry>
5972        </row>
5973
5974        <row>
5975         <entry><literal><function>localtimestamp</function></literal></entry>
5976         <entry><type>timestamp</type></entry>
5977         <entry>Current date and time (start of current transaction);
5978          see <xref linkend="functions-datetime-current">
5979         </entry>
5980         <entry></entry>
5981         <entry></entry>
5982        </row>
5983
5984        <row>
5985         <entry><literal><function>now</function>()</literal></entry>
5986         <entry><type>timestamp with time zone</type></entry>
5987         <entry>Current date and time (start of current transaction);
5988          see <xref linkend="functions-datetime-current">
5989         </entry>
5990         <entry></entry>
5991         <entry></entry>
5992        </row>
5993
5994        <row>
5995         <entry><literal><function>statement_timestamp</function>()</literal></entry>
5996         <entry><type>timestamp with time zone</type></entry>
5997         <entry>Current date and time (start of current statement);
5998          see <xref linkend="functions-datetime-current">
5999         </entry>
6000         <entry></entry>
6001         <entry></entry>
6002        </row>
6003
6004        <row>
6005         <entry><literal><function>timeofday</function>()</literal></entry>
6006         <entry><type>text</type></entry>
6007         <entry>Current date and time
6008          (like <function>clock_timestamp</>, but as a <type>text</> string);
6009          see <xref linkend="functions-datetime-current">
6010         </entry>
6011         <entry></entry>
6012         <entry></entry>
6013        </row>
6014
6015        <row>
6016         <entry><literal><function>transaction_timestamp</function>()</literal></entry>
6017         <entry><type>timestamp with time zone</type></entry>
6018         <entry>Current date and time (start of current transaction);
6019          see <xref linkend="functions-datetime-current">
6020         </entry>
6021         <entry></entry>
6022         <entry></entry>
6023        </row>
6024       </tbody>
6025      </tgroup>
6026     </table>
6027
6028    <para>
6029     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6030     supported:
6031 <synopsis>
6032 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6033 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6034 </synopsis>
6035     This expression yields true when two time periods (defined by their
6036     endpoints) overlap, false when they do not overlap.  The endpoints
6037     can be specified as pairs of dates, times, or time stamps; or as
6038     a date, time, or time stamp followed by an interval.
6039    </para>
6040
6041 <screen>
6042 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6043        (DATE '2001-10-30', DATE '2002-10-30');
6044 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6045 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6046        (DATE '2001-10-30', DATE '2002-10-30');
6047 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6048 </screen>
6049
6050   <para>
6051    When adding an <type>interval</type> value to (or subtracting an 
6052    <type>interval</type> value from) a <type>timestamp with time zone</type> 
6053    value, the days component advances (or decrements) the date of the 
6054    <type>timestamp with time zone</type> by the indicated number of days. 
6055    Across daylight saving time changes (with the session time zone set to a 
6056    time zone that recognizes DST), this means <literal>interval '1 day'</literal> 
6057    does not necessarily equal <literal>interval '24 hours'</literal>. 
6058    For example, with the session time zone set to <literal>CST7CDT</literal>,
6059    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
6060    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>, 
6061    while adding <literal>interval '24 hours'</literal> to the same initial 
6062    <type>timestamp with time zone</type> produces
6063    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6064    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone 
6065    <literal>CST7CDT</literal>.
6066   </para>
6067
6068   <para>
6069    Note there can be ambiguity in the <literal>months</> returned by
6070    <function>age</> because different months have a different number of
6071    days.  <productname>PostgreSQL</>'s approach uses the month from the
6072    earlier of the two dates when calculating partial months.  For example,
6073    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6074    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6075    days</> because May has 31 days, while April has only 30.
6076   </para>
6077
6078   <sect2 id="functions-datetime-extract">
6079    <title><function>EXTRACT</function>, <function>date_part</function></title>
6080
6081    <indexterm>
6082     <primary>date_part</primary>
6083    </indexterm>
6084    <indexterm>
6085     <primary>extract</primary>
6086    </indexterm>
6087
6088 <synopsis>
6089 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6090 </synopsis>
6091
6092    <para>
6093     The <function>extract</function> function retrieves subfields
6094     such as year or hour from date/time values.
6095     <replaceable>source</replaceable> must be a value expression of
6096     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6097     (Expressions of type <type>date</type> will
6098     be cast to <type>timestamp</type> and can therefore be used as
6099     well.)  <replaceable>field</replaceable> is an identifier or
6100     string that selects what field to extract from the source value.
6101     The <function>extract</function> function returns values of type
6102     <type>double precision</type>.
6103     The following are valid field names:
6104
6105     <!-- alphabetical -->
6106     <variablelist>
6107      <varlistentry>
6108       <term><literal>century</literal></term>
6109       <listitem>
6110        <para>
6111         The century
6112        </para>
6113
6114 <screen>
6115 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6116 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6117 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6118 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6119 </screen>
6120
6121        <para>
6122         The first century starts at 0001-01-01 00:00:00 AD, although
6123         they did not know it at the time. This definition applies to all
6124         Gregorian calendar countries. There is no century number 0,
6125         you go from -1 to 1.
6126
6127         If you disagree with this, please write your complaint to:
6128         Pope, Cathedral Saint-Peter of Roma, Vatican.
6129        </para>
6130
6131        <para>
6132         <productname>PostgreSQL</productname> releases before 8.0 did not
6133         follow the conventional numbering of centuries, but just returned
6134         the year field divided by 100.
6135        </para>
6136       </listitem>
6137      </varlistentry>
6138
6139      <varlistentry>
6140       <term><literal>day</literal></term>
6141       <listitem>
6142        <para>
6143         The day (of the month) field (1 - 31)
6144        </para>
6145
6146 <screen>
6147 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6148 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6149 </screen>
6150       </listitem>
6151      </varlistentry>
6152
6153      <varlistentry>
6154       <term><literal>decade</literal></term>
6155       <listitem>
6156        <para>
6157         The year field divided by 10
6158        </para>
6159
6160 <screen>
6161 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6162 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6163 </screen>
6164       </listitem>
6165      </varlistentry>
6166
6167      <varlistentry>
6168       <term><literal>dow</literal></term>
6169       <listitem>
6170        <para>
6171         The day of the week as Sunday(<literal>0</>) to
6172         Saturday(<literal>6</>)
6173        </para>
6174
6175 <screen>
6176 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6177 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6178 </screen>
6179        <para>
6180         Note that <function>extract</function>'s day of the week numbering
6181         is different from that of the <function>to_char(...,
6182         'D')</function> function.
6183        </para>
6184
6185       </listitem>
6186      </varlistentry>
6187
6188      <varlistentry>
6189       <term><literal>doy</literal></term>
6190       <listitem>
6191        <para>
6192         The day of the year (1 - 365/366)
6193        </para>
6194
6195 <screen>
6196 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6197 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6198 </screen>
6199       </listitem>
6200      </varlistentry>
6201
6202      <varlistentry>
6203       <term><literal>epoch</literal></term>
6204       <listitem>
6205        <para>
6206         For <type>date</type> and <type>timestamp</type> values, the
6207         number of seconds since 1970-01-01 00:00:00-00 (can be negative);
6208         for <type>interval</type> values, the total number
6209         of seconds in the interval
6210        </para>
6211
6212 <screen>
6213 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-08');
6214 <lineannotation>Result: </lineannotation><computeroutput>982384720</computeroutput>
6215
6216 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6217 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6218 </screen>
6219
6220        <para>
6221         Here is how you can convert an epoch value back to a time
6222         stamp:
6223        </para>
6224
6225 <screen>
6226 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720 * INTERVAL '1 second';
6227 </screen>
6228       </listitem>
6229      </varlistentry>
6230
6231      <varlistentry>
6232       <term><literal>hour</literal></term>
6233       <listitem>
6234        <para>
6235         The hour field (0 - 23)
6236        </para>
6237
6238 <screen>
6239 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6240 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6241 </screen>
6242       </listitem>
6243      </varlistentry>
6244
6245      <varlistentry>
6246       <term><literal>isodow</literal></term>
6247       <listitem>
6248        <para>
6249         The day of the week as Monday(<literal>1</>) to
6250         Sunday(<literal>7</>)
6251        </para>
6252
6253 <screen>
6254 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6255 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6256 </screen>
6257        <para>
6258         This is identical to <literal>dow</> except for Sunday.  This
6259         matches the <acronym>ISO</> 8601 day of the week numbering.
6260        </para>
6261
6262       </listitem>
6263      </varlistentry>
6264
6265      <varlistentry>
6266       <term><literal>isoyear</literal></term>
6267       <listitem>
6268        <para>
6269         The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals).
6270        </para>
6271
6272 <screen>
6273 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6274 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6275 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6276 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6277 </screen>
6278
6279        <para>
6280         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.
6281        </para>
6282        <para>
6283         This field is not available in PostgreSQL releases prior to 8.3.
6284        </para>
6285       </listitem>
6286      </varlistentry>
6287
6288      <varlistentry>
6289       <term><literal>microseconds</literal></term>
6290       <listitem>
6291        <para>
6292         The seconds field, including fractional parts, multiplied by 1
6293         000 000.  Note that this includes full seconds.
6294        </para>
6295
6296 <screen>
6297 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6298 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6299 </screen>
6300       </listitem>
6301      </varlistentry>
6302
6303      <varlistentry>
6304       <term><literal>millennium</literal></term>
6305       <listitem>
6306        <para>
6307         The millennium
6308        </para>
6309
6310 <screen>
6311 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6312 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6313 </screen>
6314
6315        <para>
6316         Years in the 1900s are in the second millennium.
6317         The third millennium starts January 1, 2001.
6318        </para>
6319
6320        <para>
6321         <productname>PostgreSQL</productname> releases before 8.0 did not
6322         follow the conventional numbering of millennia, but just returned
6323         the year field divided by 1000.
6324        </para>
6325       </listitem>
6326      </varlistentry>
6327
6328      <varlistentry>
6329       <term><literal>milliseconds</literal></term>
6330       <listitem>
6331        <para>
6332         The seconds field, including fractional parts, multiplied by
6333         1000.  Note that this includes full seconds.
6334        </para>
6335
6336 <screen>
6337 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6338 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6339 </screen>
6340       </listitem>
6341      </varlistentry>
6342
6343      <varlistentry>
6344       <term><literal>minute</literal></term>
6345       <listitem>
6346        <para>
6347         The minutes field (0 - 59)
6348        </para>
6349
6350 <screen>
6351 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6352 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6353 </screen>
6354       </listitem>
6355      </varlistentry>
6356
6357      <varlistentry>
6358       <term><literal>month</literal></term>
6359       <listitem>
6360        <para>
6361         For <type>timestamp</type> values, the number of the month
6362         within the year (1 - 12) ; for <type>interval</type> values
6363         the number of months, modulo 12 (0 - 11)
6364        </para>
6365
6366 <screen>
6367 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6368 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6369
6370 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6371 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6372
6373 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6374 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6375 </screen>
6376       </listitem>
6377      </varlistentry>
6378
6379      <varlistentry>
6380       <term><literal>quarter</literal></term>
6381       <listitem>
6382        <para>
6383         The quarter of the year (1 - 4) that the day is in
6384        </para>
6385
6386 <screen>
6387 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6388 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6389 </screen>
6390       </listitem>
6391      </varlistentry>
6392
6393      <varlistentry>
6394       <term><literal>second</literal></term>
6395       <listitem>
6396        <para>
6397         The seconds field, including fractional parts (0 -
6398         59<footnote><simpara>60 if leap seconds are
6399         implemented by the operating system</simpara></footnote>)
6400        </para>
6401
6402 <screen>
6403 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6404 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6405
6406 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6407 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6408 </screen>
6409       </listitem>
6410      </varlistentry>
6411      <varlistentry>
6412       <term><literal>timezone</literal></term>
6413       <listitem>
6414        <para>
6415         The time zone offset from UTC, measured in seconds.  Positive values
6416         correspond to time zones east of UTC, negative values to
6417         zones west of UTC.
6418        </para>
6419       </listitem>
6420      </varlistentry>
6421
6422      <varlistentry>
6423       <term><literal>timezone_hour</literal></term>
6424       <listitem>
6425        <para>
6426         The hour component of the time zone offset
6427        </para>
6428       </listitem>
6429      </varlistentry>
6430
6431      <varlistentry>
6432       <term><literal>timezone_minute</literal></term>
6433       <listitem>
6434        <para>
6435         The minute component of the time zone offset
6436        </para>
6437       </listitem>
6438      </varlistentry>
6439
6440      <varlistentry>
6441       <term><literal>week</literal></term>
6442       <listitem>
6443        <para>
6444         The number of the week of the year that the day is in.  By definition
6445         (<acronym>ISO</acronym> 8601), the first week of a year
6446         contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
6447         week starts on Monday.)  In other words, the first Thursday of
6448         a year is in week 1 of that year.
6449        </para>
6450        <para>
6451         Because of this, it is possible for early January dates to be part of the 
6452         52nd or 53rd week of the previous year.  For example, <literal>2005-01-01</>
6453         is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of 
6454         the 52nd week of year 2005.
6455        </para>
6456
6457 <screen>
6458 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6459 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6460 </screen>
6461       </listitem>
6462      </varlistentry>
6463
6464      <varlistentry>
6465       <term><literal>year</literal></term>
6466       <listitem>
6467        <para>
6468         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting 
6469         <literal>BC</> years from <literal>AD</> years should be done with care.
6470        </para>
6471
6472 <screen>
6473 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6474 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6475 </screen>
6476       </listitem>
6477      </varlistentry>
6478
6479     </variablelist>
6480    </para>
6481
6482    <para>
6483     The <function>extract</function> function is primarily intended
6484     for computational processing.  For formatting date/time values for
6485     display, see <xref linkend="functions-formatting">.
6486    </para>
6487
6488    <para>
6489     The <function>date_part</function> function is modeled on the traditional
6490     <productname>Ingres</productname> equivalent to the
6491     <acronym>SQL</acronym>-standard function <function>extract</function>:
6492 <synopsis>
6493 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6494 </synopsis>
6495     Note that here the <replaceable>field</replaceable> parameter needs to
6496     be a string value, not a name.  The valid field names for
6497     <function>date_part</function> are the same as for
6498     <function>extract</function>.
6499    </para>
6500
6501 <screen>
6502 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
6503 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6504
6505 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
6506 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
6507 </screen>
6508
6509   </sect2>
6510
6511   <sect2 id="functions-datetime-trunc">
6512    <title><function>date_trunc</function></title>
6513
6514    <indexterm>
6515     <primary>date_trunc</primary>
6516    </indexterm>
6517
6518    <para>
6519     The function <function>date_trunc</function> is conceptually
6520     similar to the <function>trunc</function> function for numbers.
6521    </para>
6522
6523    <para>
6524 <synopsis>
6525 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6526 </synopsis>
6527     <replaceable>source</replaceable> is a value expression of type
6528     <type>timestamp</type> or <type>interval</>.
6529     (Values of type <type>date</type> and
6530     <type>time</type> are cast automatically, to <type>timestamp</type> or
6531     <type>interval</> respectively.)
6532     <replaceable>field</replaceable> selects to which precision to
6533     truncate the input value.  The return value is of type
6534     <type>timestamp</type> or <type>interval</>
6535     with all fields that are less significant than the
6536     selected one set to zero (or one, for day and month).
6537    </para>
6538
6539    <para>
6540     Valid values for <replaceable>field</replaceable> are:
6541     <simplelist>
6542      <member><literal>microseconds</literal></member>
6543      <member><literal>milliseconds</literal></member>
6544      <member><literal>second</literal></member>
6545      <member><literal>minute</literal></member>
6546      <member><literal>hour</literal></member>
6547      <member><literal>day</literal></member>
6548      <member><literal>week</literal></member>
6549      <member><literal>month</literal></member>
6550      <member><literal>quarter</literal></member>
6551      <member><literal>year</literal></member>
6552      <member><literal>decade</literal></member>
6553      <member><literal>century</literal></member>
6554      <member><literal>millennium</literal></member>
6555     </simplelist>
6556    </para>
6557
6558    <para>
6559     Examples:
6560 <screen>
6561 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
6562 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
6563
6564 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
6565 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
6566 </screen>
6567    </para>
6568   </sect2>
6569
6570   <sect2 id="functions-datetime-zoneconvert">
6571    <title><literal>AT TIME ZONE</literal></title>
6572
6573    <indexterm>
6574     <primary>time zone</primary>
6575     <secondary>conversion</secondary>
6576    </indexterm>
6577
6578    <indexterm>
6579     <primary>AT TIME ZONE</primary>
6580    </indexterm>
6581
6582    <para>
6583     The <literal>AT TIME ZONE</literal> construct allows conversions
6584     of time stamps to different time zones.  <xref
6585     linkend="functions-datetime-zoneconvert-table"> shows its
6586     variants.
6587    </para>
6588
6589     <table id="functions-datetime-zoneconvert-table">
6590      <title><literal>AT TIME ZONE</literal> Variants</title>
6591      <tgroup cols="3">
6592       <thead>
6593        <row>
6594         <entry>Expression</entry>
6595         <entry>Return Type</entry>
6596         <entry>Description</entry>
6597        </row>
6598       </thead>
6599
6600       <tbody>
6601        <row>
6602         <entry>
6603          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6604         </entry>
6605         <entry><type>timestamp with time zone</type></entry>
6606         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
6607        </row>
6608
6609        <row>
6610         <entry>
6611          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6612         </entry>
6613         <entry><type>timestamp without time zone</type></entry>
6614         <entry>Convert given time stamp <emphasis>with time zone</> to the new time zone</entry>
6615        </row>
6616
6617        <row>
6618         <entry>
6619          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6620         </entry>
6621         <entry><type>time with time zone</type></entry>
6622         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
6623        </row>
6624       </tbody>
6625      </tgroup>
6626     </table>
6627
6628    <para>
6629     In these expressions, the desired time zone <replaceable>zone</> can be
6630     specified either as a text string (e.g., <literal>'PST'</literal>)
6631     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
6632     In the text case, a time zone name can be specified in any of the ways
6633     described in <xref linkend="datatype-timezones">.
6634    </para>
6635
6636    <para>
6637     Examples (supposing that the local time zone is <literal>PST8PDT</>):
6638 <screen>
6639 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
6640 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
6641
6642 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
6643 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
6644 </screen>
6645     The first example takes a time stamp without time zone and interprets it as MST time
6646     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes 
6647     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
6648    </para>
6649
6650    <para>
6651     The function <literal><function>timezone</function>(<replaceable>zone</>,
6652     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
6653     <literal><replaceable>timestamp</> AT TIME ZONE
6654     <replaceable>zone</></literal>. 
6655    </para>
6656   </sect2>
6657
6658   <sect2 id="functions-datetime-current">
6659    <title>Current Date/Time</title>
6660
6661    <indexterm>
6662     <primary>date</primary>
6663     <secondary>current</secondary>
6664    </indexterm>
6665
6666    <indexterm>
6667     <primary>time</primary>
6668     <secondary>current</secondary>
6669    </indexterm>
6670
6671    <para>
6672     <productname>PostgreSQL</productname> provides a number of functions
6673     that return values related to the current date and time.  These
6674     SQL-standard functions all return values based on the start time of
6675     the current transaction:
6676 <synopsis>
6677 CURRENT_DATE
6678 CURRENT_TIME
6679 CURRENT_TIMESTAMP
6680 CURRENT_TIME(<replaceable>precision</replaceable>)
6681 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
6682 LOCALTIME
6683 LOCALTIMESTAMP
6684 LOCALTIME(<replaceable>precision</replaceable>)
6685 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
6686 </synopsis>
6687     </para>
6688
6689     <para>
6690      <function>CURRENT_TIME</function> and
6691      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
6692      <function>LOCALTIME</function> and
6693      <function>LOCALTIMESTAMP</function> deliver values without time zone.
6694     </para>
6695
6696     <para>
6697      <function>CURRENT_TIME</function>,
6698      <function>CURRENT_TIMESTAMP</function>,
6699      <function>LOCALTIME</function>, and
6700      <function>LOCALTIMESTAMP</function>
6701      can optionally be given
6702      a precision parameter, which causes the result to be rounded
6703      to that many fractional digits in the seconds field.  Without a precision parameter,
6704      the result is given to the full available precision.
6705     </para>
6706
6707    <para>
6708     Some examples:
6709 <screen>
6710 SELECT CURRENT_TIME;
6711 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
6712
6713 SELECT CURRENT_DATE;
6714 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
6715
6716 SELECT CURRENT_TIMESTAMP;
6717 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
6718
6719 SELECT CURRENT_TIMESTAMP(2);
6720 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
6721
6722 SELECT LOCALTIMESTAMP;
6723 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
6724 </screen>
6725    </para>
6726
6727    <para>
6728     Since these functions return
6729     the start time of the current transaction, their values do not
6730     change during the transaction. This is considered a feature:
6731     the intent is to allow a single transaction to have a consistent
6732     notion of the <quote>current</quote> time, so that multiple
6733     modifications within the same transaction bear the same
6734     time stamp.
6735    </para>
6736
6737    <note>
6738     <para>
6739      Other database systems might advance these values more
6740      frequently.
6741     </para>
6742    </note>
6743
6744    <para>
6745     <productname>PostgreSQL</productname> also provides functions that
6746     return the start time of the current statement, as well as the actual
6747     current time at the instant the function is called.  The complete list
6748     of non-SQL-standard time functions is:
6749 <synopsis>
6750 now()
6751 transaction_timestamp()
6752 statement_timestamp()
6753 clock_timestamp()
6754 timeofday()
6755 </synopsis>
6756    </para>
6757
6758    <para>
6759     <function>now()</> is a traditional <productname>PostgreSQL</productname>
6760     equivalent to <function>CURRENT_TIMESTAMP</function>.
6761     <function>transaction_timestamp()</> is likewise equivalent to
6762     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
6763     what it returns.
6764     <function>statement_timestamp()</> returns the start time of the current
6765     statement (more specifically, the time of receipt of the latest command
6766     message from the client).
6767     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
6768     return the same value during the first command of a transaction, but might
6769     differ during subsequent commands.
6770     <function>clock_timestamp()</> returns the actual current time, and
6771     therefore its value changes even within a single SQL command.
6772     <function>timeofday()</> is a historical
6773     <productname>PostgreSQL</productname> function.  Like
6774     <function>clock_timestamp()</>, it returns the actual current time,
6775     but as a formatted <type>text</> string rather than a <type>timestamp
6776     with time zone</> value.
6777    </para>
6778
6779    <para>
6780     All the date/time data types also accept the special literal value
6781     <literal>now</literal> to specify the current date and time (again,
6782     interpreted as the transaction start time).  Thus,
6783     the following three all return the same result:
6784 <programlisting>
6785 SELECT CURRENT_TIMESTAMP;
6786 SELECT now();
6787 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
6788 </programlisting>
6789    </para>
6790
6791     <tip>
6792      <para>
6793       You do not want to use the third form when specifying a <literal>DEFAULT</>
6794       clause while creating a table.  The system will convert <literal>now</literal>
6795       to a <type>timestamp</type> as soon as the constant is parsed, so that when
6796       the default value is needed,
6797       the time of the table creation would be used!  The first two
6798       forms will not be evaluated until the default value is used,
6799       because they are function calls.  Thus they will give the desired
6800       behavior of defaulting to the time of row insertion.
6801      </para>
6802     </tip>
6803   </sect2>
6804
6805   <sect2 id="functions-datetime-delay">
6806    <title>Delaying Execution</title>
6807
6808    <indexterm>
6809     <primary>pg_sleep</primary>
6810    </indexterm>
6811    <indexterm>
6812     <primary>sleep</primary>
6813    </indexterm>
6814    <indexterm>
6815     <primary>delay</primary>
6816    </indexterm>
6817
6818    <para>
6819     The following function is available to delay execution of the server
6820     process:
6821 <synopsis>
6822 pg_sleep(<replaceable>seconds</replaceable>)
6823 </synopsis>
6824
6825     <function>pg_sleep</function> makes the current session's process
6826     sleep until <replaceable>seconds</replaceable> seconds have
6827     elapsed.  <replaceable>seconds</replaceable> is a value of type
6828     <type>double precision</>, so fractional-second delays can be specified.
6829     For example:
6830
6831 <programlisting>
6832 SELECT pg_sleep(1.5);
6833 </programlisting>
6834    </para>
6835
6836    <note>
6837      <para>
6838       The effective resolution of the sleep interval is platform-specific;
6839       0.01 seconds is a common value.  The sleep delay will be at least as long
6840       as specified. It might be longer depending on factors such as server load.
6841      </para>
6842    </note>
6843
6844    <warning>
6845      <para>
6846       Make sure that your session does not hold more locks than necessary
6847       when calling <function>pg_sleep</function>.  Otherwise other sessions
6848       might have to wait for your sleeping process, slowing down the entire
6849       system.
6850      </para>
6851    </warning>
6852   </sect2>
6853
6854  </sect1>
6855
6856   
6857  <sect1 id="functions-enum">
6858   <title>Enum Support Functions</title>
6859
6860   <para>
6861    For enum types (described in <xref linkend="datatype-enum">),
6862    there are several functions that allow cleaner programming without
6863    hard-coding particular values of an enum type.
6864    These are listed in <xref linkend="functions-enum-table">. The examples
6865    assume an enum type created as:
6866
6867 <programlisting>
6868 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
6869 </programlisting>
6870
6871   </para>
6872
6873   <table id="functions-enum-table">
6874     <title>Enum Support Functions</title>
6875     <tgroup cols="4">
6876      <thead>
6877       <row>
6878        <entry>Function</entry>
6879        <entry>Description</entry>
6880        <entry>Example</entry>
6881        <entry>Example Result</entry>
6882       </row>
6883      </thead>
6884      <tbody>
6885       <row>
6886        <entry><literal>enum_first(anyenum)</literal></entry>
6887        <entry>Returns the first value of the input enum type</entry>
6888        <entry><literal>enum_first(null::rainbow)</literal></entry>
6889        <entry><literal>red</literal></entry>
6890       </row>
6891       <row>
6892        <entry><literal>enum_last(anyenum)</literal></entry>
6893        <entry>Returns the last value of the input enum type</entry>
6894        <entry><literal>enum_last(null::rainbow)</literal></entry>
6895        <entry><literal>purple</literal></entry>
6896       </row>
6897       <row>
6898        <entry><literal>enum_range(anyenum)</literal></entry>
6899        <entry>Returns all values of the input enum type in an ordered array</entry>
6900        <entry><literal>enum_range(null::rainbow)</literal></entry>
6901        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
6902       </row>
6903       <row>
6904        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
6905        <entry morerows="2">
6906         Returns the range between the two given enum values, as an ordered
6907         array. The values must be from the same enum type. If the first
6908         parameter is null, the result will start with the first value of
6909         the enum type.
6910         If the second parameter is null, the result will end with the last
6911         value of the enum type.
6912        </entry>
6913        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
6914        <entry><literal>{orange,yellow,green}</literal></entry>
6915       </row>
6916       <row>
6917        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
6918        <entry><literal>{red,orange,yellow,green}</literal></entry>
6919       </row>
6920       <row>
6921        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
6922        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
6923       </row>
6924      </tbody>
6925     </tgroup>
6926    </table>
6927
6928    <para>
6929     Notice that except for the two-argument form of <function>enum_range</>,
6930     these functions disregard the specific value passed to them; they care
6931     only about its declared data type.  Either null or a specific value of
6932     the type can be passed, with the same result.  It is more common to
6933     apply these functions to a table column or function argument than to
6934     a hardwired type name as suggested by the examples.
6935    </para>
6936  </sect1>
6937
6938  <sect1 id="functions-geometry">
6939   <title>Geometric Functions and Operators</title>
6940
6941    <para>
6942     The geometric types <type>point</type>, <type>box</type>,
6943     <type>lseg</type>, <type>line</type>, <type>path</type>,
6944     <type>polygon</type>, and <type>circle</type> have a large set of
6945     native support functions and operators, shown in <xref
6946     linkend="functions-geometry-op-table">, <xref
6947     linkend="functions-geometry-func-table">, and <xref
6948     linkend="functions-geometry-conv-table">.
6949    </para>
6950
6951    <caution>
6952     <para>
6953      Note that the <quote>same as</> operator, <literal>~=</>, represents
6954      the usual notion of equality for the <type>point</type>,
6955      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
6956      Some of these types also have an <literal>=</> operator, but
6957      <literal>=</> compares
6958      for equal <emphasis>areas</> only.  The other scalar comparison operators
6959      (<literal>&lt;=</> and so on) likewise compare areas for these types.
6960     </para>
6961    </caution>
6962
6963    <table id="functions-geometry-op-table">
6964      <title>Geometric Operators</title>
6965      <tgroup cols="3">
6966       <thead>
6967        <row>
6968         <entry>Operator</entry>
6969         <entry>Description</entry>
6970         <entry>Example</entry>
6971        </row>
6972       </thead>
6973       <tbody>
6974        <row>
6975         <entry> <literal>+</literal> </entry>
6976         <entry>Translation</entry>
6977         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
6978        </row>
6979        <row>
6980         <entry> <literal>-</literal> </entry>
6981         <entry>Translation</entry>
6982         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
6983        </row>
6984        <row>
6985         <entry> <literal>*</literal> </entry>
6986         <entry>Scaling/rotation</entry>
6987         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
6988        </row>
6989        <row>
6990         <entry> <literal>/</literal> </entry>
6991         <entry>Scaling/rotation</entry>
6992         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
6993        </row>
6994        <row>
6995         <entry> <literal>#</literal> </entry>
6996         <entry>Point or box of intersection</entry>
6997         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
6998        </row>
6999        <row>
7000         <entry> <literal>#</literal> </entry>
7001         <entry>Number of points in path or polygon</entry>
7002         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
7003        </row>
7004        <row>
7005         <entry> <literal>@-@</literal> </entry>
7006         <entry>Length or circumference</entry>
7007         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
7008        </row>
7009        <row>
7010         <entry> <literal>@@</literal> </entry>
7011         <entry>Center</entry>
7012         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
7013        </row>
7014        <row>
7015         <entry> <literal>##</literal> </entry>
7016         <entry>Closest point to first operand on second operand</entry>
7017         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
7018        </row>
7019        <row>
7020         <entry> <literal>&lt;-&gt;</literal> </entry>
7021         <entry>Distance between</entry>
7022         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
7023        </row>
7024        <row>
7025         <entry> <literal>&amp;&amp;</literal> </entry>
7026         <entry>Overlaps?</entry>
7027         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
7028        </row>
7029        <row>
7030         <entry> <literal>&lt;&lt;</literal> </entry>
7031         <entry>Is strictly left of?</entry>
7032         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
7033        </row>
7034        <row>
7035         <entry> <literal>&gt;&gt;</literal> </entry>
7036         <entry>Is strictly right of?</entry>
7037         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
7038        </row>
7039        <row>
7040         <entry> <literal>&amp;&lt;</literal> </entry>
7041         <entry>Does not extend to the right of?</entry>
7042         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
7043        </row>
7044        <row>
7045         <entry> <literal>&amp;&gt;</literal> </entry>
7046         <entry>Does not extend to the left of?</entry>
7047         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
7048        </row>
7049        <row>
7050         <entry> <literal>&lt;&lt;|</literal> </entry>
7051         <entry>Is strictly below?</entry>
7052         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
7053        </row>
7054        <row>
7055         <entry> <literal>|&gt;&gt;</literal> </entry>
7056         <entry>Is strictly above?</entry>
7057         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
7058        </row>
7059        <row>
7060         <entry> <literal>&amp;&lt;|</literal> </entry>
7061         <entry>Does not extend above?</entry>
7062         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
7063        </row>
7064        <row>
7065         <entry> <literal>|&amp;&gt;</literal> </entry>
7066         <entry>Does not extend below?</entry>
7067         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
7068        </row>
7069        <row>
7070         <entry> <literal>&lt;^</literal> </entry>
7071         <entry>Is below (allows touching)?</entry>
7072         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
7073        </row>
7074        <row>
7075         <entry> <literal>&gt;^</literal> </entry>
7076         <entry>Is above (allows touching)?</entry>
7077         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
7078        </row>
7079        <row>
7080         <entry> <literal>?#</literal> </entry>
7081         <entry>Intersects?</entry>
7082         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7083        </row>
7084        <row>
7085         <entry> <literal>?-</literal> </entry>
7086         <entry>Is horizontal?</entry>
7087         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7088        </row>
7089        <row>
7090         <entry> <literal>?-</literal> </entry>
7091         <entry>Are horizontally aligned?</entry>
7092         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7093        </row>
7094        <row>
7095         <entry> <literal>?|</literal> </entry>
7096         <entry>Is vertical?</entry>
7097         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7098        </row>
7099        <row>
7100         <entry> <literal>?|</literal> </entry>
7101         <entry>Are vertically aligned?</entry>
7102         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7103        </row>
7104        <row>
7105         <entry> <literal>?-|</literal> </entry>
7106         <entry>Is perpendicular?</entry>
7107         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7108        </row>
7109        <row>
7110         <entry> <literal>?||</literal> </entry>
7111         <entry>Are parallel?</entry>
7112         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7113        </row>
7114        <row>
7115         <entry> <literal>@&gt;</literal> </entry>
7116         <entry>Contains?</entry>
7117         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7118        </row>
7119        <row>
7120         <entry> <literal>&lt;@</literal> </entry>
7121         <entry>Contained in or on?</entry>
7122         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7123        </row>
7124        <row>
7125         <entry> <literal>~=</literal> </entry>
7126         <entry>Same as?</entry>
7127         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7128        </row>
7129       </tbody>
7130      </tgroup>
7131    </table>
7132
7133    <note>
7134     <para>
7135      Before <productname>PostgreSQL</productname> 8.2, the containment
7136      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7137      called <literal>~</> and <literal>@</>.  These names are still
7138      available, but are deprecated and will eventually be retired.
7139     </para>
7140    </note>
7141
7142    <indexterm>
7143     <primary>area</primary>
7144    </indexterm>
7145    <indexterm>
7146     <primary>center</primary>
7147    </indexterm>
7148    <indexterm>
7149     <primary>diameter</primary>
7150    </indexterm>
7151    <indexterm>
7152     <primary>height</primary>
7153    </indexterm>
7154    <indexterm>
7155     <primary>isclosed</primary>
7156    </indexterm>
7157    <indexterm>
7158     <primary>isopen</primary>
7159    </indexterm>
7160    <indexterm>
7161     <primary>length</primary>
7162    </indexterm>
7163    <indexterm>
7164     <primary>npoints</primary>
7165    </indexterm>
7166    <indexterm>
7167     <primary>pclose</primary>
7168    </indexterm>
7169    <indexterm>
7170     <primary>popen</primary>
7171    </indexterm>
7172    <indexterm>
7173     <primary>radius</primary>
7174    </indexterm>
7175    <indexterm>
7176     <primary>width</primary>
7177    </indexterm>
7178
7179    <table id="functions-geometry-func-table">
7180      <title>Geometric Functions</title>
7181      <tgroup cols="4">
7182       <thead>
7183        <row>
7184         <entry>Function</entry>
7185         <entry>Return Type</entry>
7186         <entry>Description</entry>
7187         <entry>Example</entry>
7188        </row>
7189       </thead>
7190       <tbody>
7191        <row>
7192         <entry><literal><function>area</function>(<replaceable>object</>)</literal></entry>
7193         <entry><type>double precision</type></entry>
7194         <entry>area</entry>
7195         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7196        </row>
7197        <row>
7198         <entry><literal><function>center</function>(<replaceable>object</>)</literal></entry>
7199         <entry><type>point</type></entry>
7200         <entry>center</entry>
7201         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7202        </row>
7203        <row>
7204         <entry><literal><function>diameter</function>(<type>circle</>)</literal></entry>
7205         <entry><type>double precision</type></entry>
7206         <entry>diameter of circle</entry>
7207         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7208        </row>
7209        <row>
7210         <entry><literal><function>height</function>(<type>box</>)</literal></entry>
7211         <entry><type>double precision</type></entry>
7212         <entry>vertical size of box</entry>
7213         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7214        </row>
7215        <row>
7216         <entry><literal><function>isclosed</function>(<type>path</>)</literal></entry>
7217         <entry><type>boolean</type></entry>
7218         <entry>a closed path?</entry>
7219         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7220        </row>
7221        <row>
7222         <entry><literal><function>isopen</function>(<type>path</>)</literal></entry>
7223         <entry><type>boolean</type></entry>
7224         <entry>an open path?</entry>
7225         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7226        </row>
7227        <row>
7228         <entry><literal><function>length</function>(<replaceable>object</>)</literal></entry>
7229         <entry><type>double precision</type></entry>
7230         <entry>length</entry>
7231         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7232        </row>
7233        <row>
7234         <entry><literal><function>npoints</function>(<type>path</>)</literal></entry>
7235         <entry><type>int</type></entry>
7236         <entry>number of points</entry>
7237         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7238        </row>
7239        <row>
7240         <entry><literal><function>npoints</function>(<type>polygon</>)</literal></entry>
7241         <entry><type>int</type></entry>
7242         <entry>number of points</entry>
7243         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7244        </row>
7245        <row>
7246         <entry><literal><function>pclose</function>(<type>path</>)</literal></entry>
7247         <entry><type>path</type></entry>
7248         <entry>convert path to closed</entry>
7249         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7250        </row>
7251 <![IGNORE[
7252 <!-- Not defined by this name. Implements the intersection operator '#' -->
7253        <row>
7254         <entry><literal><function>point</function>(<type>lseg</>, <type>lseg</>)</literal></entry>
7255         <entry><type>point</type></entry>
7256         <entry>intersection</entry>
7257         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7258        </row>
7259 ]]>
7260        <row>
7261         <entry><literal><function>popen</function>(<type>path</>)</literal></entry>
7262         <entry><type>path</type></entry>
7263         <entry>convert path to open</entry>
7264         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7265        </row>
7266        <row>
7267         <entry><literal><function>radius</function>(<type>circle</type>)</literal></entry>
7268         <entry><type>double precision</type></entry>
7269         <entry>radius of circle</entry>
7270         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7271        </row>
7272        <row>
7273         <entry><literal><function>width</function>(<type>box</>)</literal></entry>
7274         <entry><type>double precision</type></entry>
7275         <entry>horizontal size of box</entry>
7276         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7277        </row>
7278       </tbody>
7279      </tgroup>
7280    </table>
7281
7282    <table id="functions-geometry-conv-table">
7283      <title>Geometric Type Conversion Functions</title>
7284      <tgroup cols="4">
7285       <thead>
7286        <row>
7287         <entry>Function</entry>
7288         <entry>Return Type</entry>
7289         <entry>Description</entry>
7290         <entry>Example</entry>
7291        </row>
7292       </thead>
7293       <tbody>
7294        <row>
7295         <entry><literal><function>box</function>(<type>circle</type>)</literal></entry>
7296         <entry><type>box</type></entry>
7297         <entry>circle to box</entry>
7298         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7299        </row>
7300        <row>
7301         <entry><literal><function>box</function>(<type>point</type>, <type>point</type>)</literal></entry>
7302         <entry><type>box</type></entry>
7303         <entry>points to box</entry>
7304         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7305        </row>
7306        <row>
7307         <entry><literal><function>box</function>(<type>polygon</type>)</literal></entry>
7308         <entry><type>box</type></entry>
7309         <entry>polygon to box</entry>
7310         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7311        </row>
7312        <row>
7313         <entry><literal><function>circle</function>(<type>box</type>)</literal></entry>
7314         <entry><type>circle</type></entry>
7315         <entry>box to circle</entry>
7316         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7317        </row>
7318        <row>
7319         <entry><literal><function>circle</function>(<type>point</type>, <type>double precision</type>)</literal></entry>
7320         <entry><type>circle</type></entry>
7321         <entry>center and radius to circle</entry>
7322         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7323        </row>
7324        <row>
7325         <entry><literal><function>circle</function>(<type>polygon</type>)</literal></entry>
7326         <entry><type>circle</type></entry>
7327         <entry>polygon to circle</entry>
7328         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7329        </row>
7330        <row>
7331         <entry><literal><function>lseg</function>(<type>box</type>)</literal></entry>
7332         <entry><type>lseg</type></entry>
7333         <entry>box diagonal to line segment</entry>
7334         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7335        </row>
7336        <row>
7337         <entry><literal><function>lseg</function>(<type>point</type>, <type>point</type>)</literal></entry>
7338         <entry><type>lseg</type></entry>
7339         <entry>points to line segment</entry>
7340         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7341        </row>
7342        <row>
7343         <entry><literal><function>path</function>(<type>polygon</type>)</literal></entry>
7344         <entry><type>point</type></entry>
7345         <entry>polygon to path</entry>
7346         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7347        </row>
7348        <row>
7349         <entry><literal><function>point</function>(<type>double
7350          precision</type>, <type>double precision</type>)</literal></entry>
7351         <entry><type>point</type></entry>
7352         <entry>construct point</entry>
7353         <entry><literal>point(23.4, -44.5)</literal></entry>
7354        </row>
7355        <row>
7356         <entry><literal><function>point</function>(<type>box</type>)</literal></entry>
7357         <entry><type>point</type></entry>
7358         <entry>center of box</entry>
7359         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7360        </row>
7361        <row>
7362         <entry><literal><function>point</function>(<type>circle</type>)</literal></entry>
7363         <entry><type>point</type></entry>
7364         <entry>center of circle</entry>
7365         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7366        </row>
7367        <row>
7368         <entry><literal><function>point</function>(<type>lseg</type>)</literal></entry>
7369         <entry><type>point</type></entry>
7370         <entry>center of line segment</entry>
7371         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7372        </row>
7373        <row>
7374         <entry><literal><function>point</function>(<type>polygon</type>)</literal></entry>
7375         <entry><type>point</type></entry>
7376         <entry>center of polygon</entry>
7377         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7378        </row>
7379        <row>
7380         <entry><literal><function>polygon</function>(<type>box</type>)</literal></entry>
7381         <entry><type>polygon</type></entry>
7382         <entry>box to 4-point polygon</entry>
7383         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7384        </row>
7385        <row>
7386         <entry><literal><function>polygon</function>(<type>circle</type>)</literal></entry>
7387         <entry><type>polygon</type></entry>
7388         <entry>circle to 12-point polygon</entry>
7389         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7390        </row>
7391        <row>
7392         <entry><literal><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</literal></entry>
7393         <entry><type>polygon</type></entry>
7394         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
7395         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7396        </row>
7397        <row>
7398         <entry><literal><function>polygon</function>(<type>path</type>)</literal></entry>
7399         <entry><type>polygon</type></entry>
7400         <entry>path to polygon</entry>
7401         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7402        </row>
7403       </tbody>
7404      </tgroup>
7405    </table>
7406
7407     <para>
7408      It is possible to access the two component numbers of a <type>point</>
7409      as though it were an array with indices 0 and 1.  For example, if
7410      <literal>t.p</> is a <type>point</> column then
7411      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7412      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7413      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7414      as an array of two <type>point</> values.
7415     </para>
7416
7417     <para>
7418      The <function>area</function> function works for the types
7419      <type>box</type>, <type>circle</type>, and <type>path</type>.
7420      The <function>area</function> function only works on the
7421      <type>path</type> data type if the points in the
7422      <type>path</type> are non-intersecting.  For example, the
7423      <type>path</type>
7424      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7425      won't work, however, the following visually identical
7426      <type>path</type>
7427      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7428      will work.  If the concept of an intersecting versus
7429      non-intersecting <type>path</type> is confusing, draw both of the
7430      above <type>path</type>s side by side on a piece of graph paper.
7431     </para>
7432
7433   </sect1>
7434
7435
7436  <sect1 id="functions-net">
7437   <title>Network Address Functions and Operators</title>
7438
7439   <para>
7440    <xref linkend="cidr-inet-operators-table"> shows the operators
7441    available for the <type>cidr</type> and <type>inet</type> types.
7442    The operators <literal>&lt;&lt;</literal>,
7443    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
7444    <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
7445    consider only the network parts of the two addresses, ignoring any
7446    host part, and determine whether one network part is identical to
7447    or a subnet of the other.
7448   </para>
7449
7450     <table id="cidr-inet-operators-table">
7451      <title><type>cidr</type> and <type>inet</type> Operators</title>
7452      <tgroup cols="3">
7453       <thead>
7454        <row>
7455         <entry>Operator</entry>
7456         <entry>Description</entry>
7457         <entry>Example</entry>
7458        </row>
7459       </thead>
7460       <tbody>
7461        <row>
7462         <entry> <literal>&lt;</literal> </entry>
7463         <entry>is less than</entry>
7464         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
7465        </row>
7466        <row>
7467         <entry> <literal>&lt;=</literal> </entry>
7468         <entry>is less than or equal</entry>
7469         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
7470        </row>
7471        <row>
7472         <entry> <literal>=</literal> </entry>
7473         <entry>equals</entry>
7474         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
7475        </row>
7476        <row>
7477         <entry> <literal>&gt;=</literal> </entry>
7478         <entry>is greater or equal</entry>
7479         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
7480        </row>
7481        <row>
7482         <entry> <literal>&gt;</literal> </entry>
7483         <entry>is greater than</entry>
7484         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
7485        </row>
7486        <row>
7487         <entry> <literal>&lt;&gt;</literal> </entry>
7488         <entry>is not equal</entry>
7489         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
7490        </row>
7491        <row>
7492         <entry> <literal>&lt;&lt;</literal> </entry>
7493         <entry>is contained within</entry>
7494         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
7495        </row>
7496        <row>
7497         <entry> <literal>&lt;&lt;=</literal> </entry>
7498         <entry>is contained within or equals</entry>
7499         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
7500        </row>
7501        <row>
7502         <entry> <literal>&gt;&gt;</literal> </entry>
7503         <entry>contains</entry>
7504         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
7505        </row>
7506        <row>
7507         <entry> <literal>&gt;&gt;=</literal> </entry>
7508         <entry>contains or equals</entry>
7509         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
7510        </row>
7511        <row>
7512         <entry> <literal>~</literal> </entry>
7513         <entry>bitwise NOT</entry>
7514         <entry><literal>~ inet '192.168.1.6'</literal></entry>
7515        </row>
7516        <row>
7517         <entry> <literal>&amp;</literal> </entry>
7518         <entry>bitwise AND</entry>
7519         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
7520        </row>
7521        <row>
7522         <entry> <literal>|</literal> </entry>
7523         <entry>bitwise OR</entry>
7524         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
7525        </row>
7526        <row>
7527         <entry> <literal>+</literal> </entry>
7528         <entry>addition</entry>
7529         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
7530        </row>
7531        <row>
7532         <entry> <literal>-</literal> </entry>
7533         <entry>subtraction</entry>
7534         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
7535        </row>
7536        <row>
7537         <entry> <literal>-</literal> </entry>
7538         <entry>subtraction</entry>
7539         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
7540        </row>
7541       </tbody>
7542      </tgroup>
7543     </table>
7544
7545   <para>
7546    <xref linkend="cidr-inet-functions-table"> shows the functions
7547    available for use with the <type>cidr</type> and <type>inet</type>
7548    types.  The <function>host</function>,
7549    <function>text</function>, and <function>abbrev</function>
7550    functions are primarily intended to offer alternative display
7551    formats.
7552   </para>
7553
7554     <table id="cidr-inet-functions-table">
7555      <title><type>cidr</type> and <type>inet</type> Functions</title>
7556      <tgroup cols="5">
7557       <thead>
7558        <row>
7559         <entry>Function</entry>
7560         <entry>Return Type</entry>
7561         <entry>Description</entry>
7562         <entry>Example</entry>
7563         <entry>Result</entry>
7564        </row>
7565       </thead>
7566       <tbody>
7567        <row>
7568         <entry><literal><function>abbrev</function>(<type>inet</type>)</literal></entry>
7569         <entry><type>text</type></entry>
7570         <entry>abbreviated display format as text</entry>
7571         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
7572         <entry><literal>10.1.0.0/16</literal></entry>
7573        </row>
7574        <row>
7575         <entry><literal><function>abbrev</function>(<type>cidr</type>)</literal></entry>
7576         <entry><type>text</type></entry>
7577         <entry>abbreviated display format as text</entry>
7578         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
7579         <entry><literal>10.1/16</literal></entry>
7580        </row>
7581        <row>
7582         <entry><literal><function>broadcast</function>(<type>inet</type>)</literal></entry>
7583         <entry><type>inet</type></entry>
7584         <entry>broadcast address for network</entry>
7585         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
7586         <entry><literal>192.168.1.255/24</literal></entry>
7587        </row>
7588        <row>
7589         <entry><literal><function>family</function>(<type>inet</type>)</literal></entry>
7590         <entry><type>int</type></entry>
7591         <entry>extract family of address; <literal>4</literal> for IPv4,
7592          <literal>6</literal> for IPv6</entry>
7593         <entry><literal>family('::1')</literal></entry>
7594         <entry><literal>6</literal></entry>
7595        </row>
7596        <row>
7597         <entry><literal><function>host</function>(<type>inet</type>)</literal></entry>
7598         <entry><type>text</type></entry>
7599         <entry>extract IP address as text</entry>
7600         <entry><literal>host('192.168.1.5/24')</literal></entry>
7601         <entry><literal>192.168.1.5</literal></entry>
7602        </row>
7603        <row>
7604         <entry><literal><function>hostmask</function>(<type>inet</type>)</literal></entry>
7605         <entry><type>inet</type></entry>
7606         <entry>construct host mask for network</entry>
7607         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
7608         <entry><literal>0.0.0.3</literal></entry>
7609        </row>
7610        <row>
7611         <entry><literal><function>masklen</function>(<type>inet</type>)</literal></entry>
7612         <entry><type>int</type></entry>
7613         <entry>extract netmask length</entry>
7614         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
7615         <entry><literal>24</literal></entry>
7616        </row>
7617        <row>
7618         <entry><literal><function>netmask</function>(<type>inet</type>)</literal></entry>
7619         <entry><type>inet</type></entry>
7620         <entry>construct netmask for network</entry>
7621         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
7622         <entry><literal>255.255.255.0</literal></entry>
7623        </row>
7624        <row>
7625         <entry><literal><function>network</function>(<type>inet</type>)</literal></entry>
7626         <entry><type>cidr</type></entry>
7627         <entry>extract network part of address</entry>
7628         <entry><literal>network('192.168.1.5/24')</literal></entry>
7629         <entry><literal>192.168.1.0/24</literal></entry>
7630        </row>
7631        <row>
7632         <entry><literal><function>set_masklen</function>(<type>inet</type>, <type>int</type>)</literal></entry>
7633         <entry><type>inet</type></entry>
7634         <entry>set netmask length for <type>inet</type> value</entry>
7635         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
7636         <entry><literal>192.168.1.5/16</literal></entry>
7637        </row>
7638        <row>
7639         <entry><literal><function>set_masklen</function>(<type>cidr</type>, <type>int</type>)</literal></entry>
7640         <entry><type>cidr</type></entry>
7641         <entry>set netmask length for <type>cidr</type> value</entry>
7642         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
7643         <entry><literal>192.168.0.0/16</literal></entry>
7644        </row>
7645        <row>
7646         <entry><literal><function>text</function>(<type>inet</type>)</literal></entry>
7647         <entry><type>text</type></entry>
7648         <entry>extract IP address and netmask length as text</entry>
7649         <entry><literal>text(inet '192.168.1.5')</literal></entry>
7650         <entry><literal>192.168.1.5/32</literal></entry>
7651        </row>
7652       </tbody>
7653      </tgroup>
7654     </table>
7655
7656   <para>
7657    Any <type>cidr</> value can be cast to <type>inet</> implicitly
7658    or explicitly; therefore, the functions shown above as operating on
7659    <type>inet</> also work on <type>cidr</> values.  (Where there are
7660    separate functions for <type>inet</> and <type>cidr</>, it is because
7661    the behavior should be different for the two cases.)
7662    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
7663    When this is done, any bits to the right of the netmask are silently zeroed
7664    to create a valid <type>cidr</> value.
7665    In addition,
7666    you can cast a text value to <type>inet</> or <type>cidr</>
7667    using normal casting syntax: for example,
7668    <literal>inet(<replaceable>expression</>)</literal> or
7669    <literal><replaceable>colname</>::cidr</literal>.
7670   </para>
7671
7672   <para>
7673    <xref linkend="macaddr-functions-table"> shows the functions
7674    available for use with the <type>macaddr</type> type.  The function
7675    <literal><function>trunc</function>(<type>macaddr</type>)</literal> returns a MAC
7676    address with the last 3 bytes set to zero.  This can be used to
7677    associate the remaining prefix with a manufacturer.
7678   </para>
7679
7680     <table id="macaddr-functions-table">
7681      <title><type>macaddr</type> Functions</title>
7682      <tgroup cols="5">
7683       <thead>
7684        <row>
7685         <entry>Function</entry>
7686         <entry>Return Type</entry>
7687         <entry>Description</entry>
7688         <entry>Example</entry>
7689         <entry>Result</entry>
7690        </row>
7691       </thead>
7692       <tbody>
7693        <row>
7694         <entry><literal><function>trunc</function>(<type>macaddr</type>)</literal></entry>
7695         <entry><type>macaddr</type></entry>
7696         <entry>set last 3 bytes to zero</entry>
7697         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
7698         <entry><literal>12:34:56:00:00:00</literal></entry>
7699        </row>
7700       </tbody>
7701      </tgroup>
7702     </table>
7703
7704    <para>
7705     The <type>macaddr</type> type also supports the standard relational
7706     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
7707     lexicographical ordering.
7708    </para>
7709
7710   </sect1>
7711
7712
7713  <sect1 id="functions-textsearch">
7714   <title>Text Search Functions and Operators</title>
7715
7716    <indexterm zone="datatype-textsearch">
7717     <primary>full text search</primary>
7718     <secondary>functions and operators</secondary>
7719    </indexterm>
7720
7721    <indexterm zone="datatype-textsearch">
7722     <primary>text search</primary>
7723     <secondary>functions and operators</secondary>
7724    </indexterm>
7725
7726   <para>
7727    <xref linkend="textsearch-operators-table">,
7728    <xref linkend="textsearch-functions-table"> and
7729    <xref linkend="textsearch-functions-debug-table">
7730    summarize the functions and operators that are provided
7731    for full text searching.  See <xref linkend="textsearch"> for a detailed
7732    explanation of <productname>PostgreSQL</productname>'s text search
7733    facility.
7734   </para>
7735
7736     <table id="textsearch-operators-table">
7737      <title>Text Search Operators</title>
7738      <tgroup cols="4">
7739       <thead>
7740        <row>
7741         <entry>Operator</entry>
7742         <entry>Description</entry>
7743         <entry>Example</entry>
7744         <entry>Result</entry>
7745        </row>
7746       </thead>
7747       <tbody>
7748        <row>
7749         <entry> <literal>@@</literal> </entry>
7750         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
7751         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
7752         <entry><literal>t</literal></entry>
7753        </row>
7754        <row>
7755         <entry> <literal>@@@</literal> </entry>
7756         <entry>deprecated synonym for <literal>@@</></entry>
7757         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
7758         <entry><literal>t</literal></entry>
7759        </row>
7760        <row>
7761         <entry> <literal>||</literal> </entry>
7762         <entry>concatenate <type>tsvector</>s</entry>
7763         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
7764         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
7765        </row>
7766        <row>
7767         <entry> <literal>&amp;&amp;</literal> </entry>
7768         <entry>AND <type>tsquery</>s together</entry>
7769         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
7770         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
7771        </row>
7772        <row>
7773         <entry> <literal>||</literal> </entry>
7774         <entry>OR <type>tsquery</>s together</entry>
7775         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
7776         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
7777        </row>
7778        <row>
7779         <entry> <literal>!!</literal> </entry>
7780         <entry>negate a <type>tsquery</></entry>
7781         <entry><literal>!! 'cat'::tsquery</literal></entry>
7782         <entry><literal>!'cat'</literal></entry>
7783        </row>
7784        <row>
7785         <entry> <literal>@&gt;</literal> </entry>
7786         <entry><type>tsquery</> contains another ?</entry>
7787         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
7788         <entry><literal>f</literal></entry>
7789        </row>
7790        <row>
7791         <entry> <literal>&lt;@</literal> </entry>
7792         <entry><type>tsquery</> is contained in ?</entry>
7793         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
7794         <entry><literal>t</literal></entry>
7795        </row>
7796       </tbody>
7797      </tgroup>
7798     </table>
7799
7800     <note>
7801      <para>
7802       The <type>tsquery</> containment operators consider only the lexemes
7803       listed in the two queries, ignoring the combining operators.
7804      </para>
7805     </note>
7806
7807     <para>
7808      In addition to the operators shown in the table, the ordinary B-tree
7809      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
7810      for types <type>tsvector</> and <type>tsquery</>.  These are not very
7811      useful for text searching but allow, for example, unique indexes to be
7812      built on columns of these types.
7813     </para>
7814
7815     <table id="textsearch-functions-table">
7816      <title>Text Search Functions</title>
7817      <tgroup cols="5">
7818       <thead>
7819        <row>
7820         <entry>Function</entry>
7821         <entry>Return Type</entry>
7822         <entry>Description</entry>
7823         <entry>Example</entry>
7824         <entry>Result</entry>
7825        </row>
7826       </thead>
7827       <tbody>
7828        <row>
7829         <entry><literal><function>to_tsvector</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</literal></entry>
7830         <entry><type>tsvector</type></entry>
7831         <entry>reduce document text to <type>tsvector</></entry>
7832         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
7833         <entry><literal>'fat':2 'rat':3</literal></entry>
7834        </row>
7835        <row>
7836         <entry><literal><function>length</function>(<type>tsvector</>)</literal></entry>
7837         <entry><type>integer</type></entry>
7838         <entry>number of lexemes in <type>tsvector</></entry>
7839         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7840         <entry><literal>3</literal></entry>
7841        </row>
7842        <row>
7843         <entry><literal><function>setweight</function>(<type>tsvector</>, <type>"char"</>)</literal></entry>
7844         <entry><type>tsvector</type></entry>
7845         <entry>assign weight to each element of <type>tsvector</></entry>
7846         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
7847         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
7848        </row>
7849        <row>
7850         <entry><literal><function>strip</function>(<type>tsvector</>)</literal></entry>
7851         <entry><type>tsvector</type></entry>
7852         <entry>remove positions and weights from <type>tsvector</></entry>
7853         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7854         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
7855        </row>
7856        <row>
7857         <entry><literal><function>to_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7858         <entry><type>tsquery</type></entry>
7859         <entry>normalize words and convert to <type>tsquery</></entry>
7860         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
7861         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7862        </row>
7863        <row>
7864         <entry><literal><function>plainto_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7865         <entry><type>tsquery</type></entry>
7866         <entry>produce <type>tsquery</> ignoring punctuation</entry>
7867         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
7868         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7869        </row>
7870        <row>
7871         <entry><literal><function>numnode</function>(<type>tsquery</>)</literal></entry>
7872         <entry><type>integer</type></entry>
7873         <entry>number of lexemes plus operators in <type>tsquery</></entry>
7874         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
7875         <entry><literal>5</literal></entry>
7876        </row>
7877        <row>
7878         <entry><literal><function>querytree</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</literal></entry>
7879         <entry><type>text</type></entry>
7880         <entry>get indexable part of a <type>tsquery</></entry>
7881         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
7882         <entry><literal>'foo'</literal></entry>
7883        </row>
7884        <row>
7885         <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>
7886         <entry><type>float4</type></entry>
7887         <entry>rank document for query</entry>
7888         <entry><literal>ts_rank(textsearch, query)</literal></entry>
7889         <entry><literal>0.818</literal></entry>
7890        </row>
7891        <row>
7892         <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>
7893         <entry><type>float4</type></entry>
7894         <entry>rank document for query using cover density</entry>
7895         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
7896         <entry><literal>2.01317</literal></entry>
7897        </row>
7898        <row>
7899         <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>
7900         <entry><type>text</type></entry>
7901         <entry>display a query match</entry>
7902         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
7903         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
7904        </row>
7905        <row>
7906         <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>
7907         <entry><type>tsquery</type></entry>
7908         <entry>replace target with substitute within query</entry>
7909         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
7910         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7911        </row>
7912        <row>
7913         <entry><literal><function>ts_rewrite</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</literal></entry>
7914         <entry><type>tsquery</type></entry>
7915         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
7916         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
7917         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7918        </row>
7919        <row>
7920         <entry><literal><function>get_current_ts_config</function>()</literal></entry>
7921         <entry><type>regconfig</type></entry>
7922         <entry>get default text search configuration</entry>
7923         <entry><literal>get_current_ts_config()</literal></entry>
7924         <entry><literal>english</literal></entry>
7925        </row>
7926        <row>
7927         <entry><literal><function>tsvector_update_trigger</function>()</literal></entry>
7928         <entry><type>trigger</type></entry>
7929         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7930         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
7931         <entry><literal></literal></entry>
7932        </row>
7933        <row>
7934         <entry><literal><function>tsvector_update_trigger_column</function>()</literal></entry>
7935         <entry><type>trigger</type></entry>
7936         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7937         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
7938         <entry><literal></literal></entry>
7939         <entry><literal></literal></entry>
7940        </row>
7941       </tbody>
7942      </tgroup>
7943     </table>
7944
7945   <note>
7946    <para>
7947     All the text search functions that accept an optional <type>regconfig</>
7948     argument will use the configuration specified by
7949     <xref linkend="guc-default-text-search-config">
7950     when that argument is omitted.
7951    </para>
7952   </note>
7953
7954   <para>
7955    The functions in
7956    <xref linkend="textsearch-functions-debug-table">
7957    are listed separately because they are not usually used in everyday text
7958    searching operations.  They are helpful for development and debugging
7959    of new text search configurations.
7960   </para>
7961
7962     <table id="textsearch-functions-debug-table">
7963      <title>Text Search Debugging Functions</title>
7964      <tgroup cols="5">
7965       <thead>
7966        <row>
7967         <entry>Function</entry>
7968         <entry>Return Type</entry>
7969         <entry>Description</entry>
7970         <entry>Example</entry>
7971         <entry>Result</entry>
7972        </row>
7973       </thead>
7974       <tbody>
7975        <row>
7976         <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>
7977         <entry><type>setof record</type></entry>
7978         <entry>test a configuration</entry>
7979         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
7980         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
7981        </row>
7982        <row>
7983         <entry><literal><function>ts_lexize</function>(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</literal></entry>
7984         <entry><type>text[]</type></entry>
7985         <entry>test a dictionary</entry>
7986         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
7987         <entry><literal>{star}</literal></entry>
7988        </row>
7989        <row>
7990         <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>
7991         <entry><type>setof record</type></entry>
7992         <entry>test a parser</entry>
7993         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
7994         <entry><literal>(1,foo) ...</literal></entry>
7995        </row>
7996        <row>
7997         <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>
7998         <entry><type>setof record</type></entry>
7999         <entry>test a parser</entry>
8000         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
8001         <entry><literal>(1,foo) ...</literal></entry>
8002        </row>
8003        <row>
8004         <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>
8005         <entry><type>setof record</type></entry>
8006         <entry>get token types defined by parser</entry>
8007         <entry><literal>ts_token_type('default')</literal></entry>
8008         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8009        </row>
8010        <row>
8011         <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>
8012         <entry><type>setof record</type></entry>
8013         <entry>get token types defined by parser</entry>
8014         <entry><literal>ts_token_type(3722)</literal></entry>
8015         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8016        </row>
8017        <row>
8018         <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>
8019         <entry><type>setof record</type></entry>
8020         <entry>get statistics of a <type>tsvector</> column</entry>
8021         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
8022         <entry><literal>(foo,10,15) ...</literal></entry>
8023        </row>
8024       </tbody>
8025      </tgroup>
8026     </table>
8027
8028  </sect1>
8029
8030
8031  <sect1 id="functions-xml">
8032   <title>XML Functions</title>
8033
8034   <para>
8035    The functions and function-like expressions described in this
8036    section operate on values of type <type>xml</type>.  Check <xref
8037    linkend="datatype-xml"> for information about the <type>xml</type>
8038    type.  The function-like expressions <function>xmlparse</function>
8039    and <function>xmlserialize</function> for converting to and from
8040    type <type>xml</type> are not repeated here.  Use of many of these
8041    functions requires the installation to have been built
8042    with <command>configure --with-libxml</>.
8043   </para>
8044
8045   <sect2>
8046    <title>Producing XML Content</title>
8047
8048    <para>
8049     A set of functions and function-like expressions are available for
8050     producing XML content from SQL data.  As such, they are
8051     particularly suitable for formatting query results into XML
8052     documents for processing in client applications.
8053    </para>
8054
8055    <sect3>
8056     <title><literal>xmlcomment</literal></title>
8057
8058     <indexterm>
8059      <primary>xmlcomment</primary>
8060     </indexterm>
8061
8062 <synopsis>
8063 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8064 </synopsis>
8065
8066     <para>
8067      The function <function>xmlcomment</function> creates an XML value
8068      containing an XML comment with the specified text as content.
8069      The text cannot contain <literal>--</literal> or end with a
8070      <literal>-</literal> so that the resulting construct is a valid
8071      XML comment.  If the argument is null, the result is null.
8072     </para>
8073
8074     <para>
8075      Example:
8076 <screen><![CDATA[
8077 SELECT xmlcomment('hello');
8078
8079   xmlcomment
8080 --------------
8081  <!--hello-->
8082 ]]></screen>
8083     </para>
8084    </sect3>
8085
8086    <sect3>
8087     <title><literal>xmlconcat</literal></title>
8088
8089     <indexterm>
8090      <primary>xmlconcat</primary>
8091     </indexterm>
8092
8093  <synopsis>
8094  <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8095  </synopsis>
8096  
8097     <para>
8098      The function <function>xmlconcat</function> concatenates a list
8099      of individual XML values to create a single value containing an
8100      XML content fragment.  Null values are omitted; the result is
8101      only null if there are no nonnull arguments.
8102     </para>
8103
8104     <para>
8105      Example:
8106 <screen><![CDATA[
8107 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8108
8109       xmlconcat
8110 ----------------------
8111  <abc/><bar>foo</bar>
8112 ]]></screen>
8113     </para>
8114
8115     <para>
8116      XML declarations, if present, are combined as follows.  If all
8117      argument values have the same XML version declaration, that
8118      version is used in the result, else no version is used.  If all
8119      argument values have the standalone declaration value
8120      <quote>yes</quote>, then that value is used in the result.  If
8121      all argument values have a standalone declaration value and at
8122      least one is <quote>no</quote>, then that is used in the result.
8123      Else the result will have no standalone declaration.  If the
8124      result is determined to require a standalone declaration but no
8125      version declaration, a version declaration with version 1.0 will
8126      be used because XML requires an XML declaration to contain a
8127      version declaration.  Encoding declarations are ignored and
8128      removed in all cases.
8129     </para>
8130
8131     <para>
8132      Example:
8133 <screen><![CDATA[
8134 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
8135
8136              xmlconcat
8137 -----------------------------------
8138  <?xml version="1.1"?><foo/><bar/>
8139 ]]></screen>
8140     </para>
8141    </sect3>
8142  
8143    <sect3>
8144     <title><literal>xmlelement</literal></title>
8145  
8146    <indexterm>
8147     <primary>xmlelement</primary>
8148    </indexterm>
8149  
8150 <synopsis>
8151  <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>)
8152  </synopsis>
8153  
8154     <para>
8155      The <function>xmlelement</function> expression produces an XML
8156      element with the given name, attributes, and content.
8157     </para>
8158
8159     <para>
8160      Examples:
8161 <screen><![CDATA[
8162 SELECT xmlelement(name foo);
8163
8164  xmlelement
8165 ------------
8166  <foo/>
8167
8168 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8169
8170     xmlelement
8171 ------------------
8172  <foo bar="xyz"/>
8173
8174 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8175
8176              xmlelement
8177 -------------------------------------
8178  <foo bar="2007-01-26">content</foo>
8179 ]]></screen>
8180     </para>
8181
8182     <para>
8183      Element and attribute names that are not valid XML names are
8184      escaped by replacing the offending characters by the sequence
8185      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8186      <replaceable>HHHH</replaceable> is the character's Unicode
8187      codepoint in hexadecimal notation.  For example:
8188 <screen><![CDATA[
8189 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
8190
8191             xmlelement
8192 ----------------------------------
8193  <foo_x0024_bar a_x0026_b="xyz"/>
8194 ]]></screen>
8195     </para>
8196
8197     <para>
8198      An explicit attribute name need not be specified if the attribute
8199      value is a column reference, in which case the column's name will
8200      be used as attribute name by default.  In any other case, the
8201      attribute must be given an explicit name.  So this example is
8202      valid:
8203 <screen>
8204 CREATE TABLE test (a xml, b xml);
8205 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8206 </screen>
8207      But these are not:
8208 <screen>
8209 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8210 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8211 </screen>
8212     </para>
8213
8214     <para>
8215      Element content, if specified, will be formatted according to
8216      data type.  If the content is itself of type <type>xml</type>,
8217      complex XML documents can be constructed.  For example:
8218 <screen><![CDATA[
8219 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8220                             xmlelement(name abc),
8221                             xmlcomment('test'),
8222                             xmlelement(name xyz));
8223
8224                   xmlelement
8225 ----------------------------------------------
8226  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
8227 ]]></screen>
8228
8229      Content of other types will be formatted into valid XML character
8230      data.  This means in particular that the characters &lt;, &gt;,
8231      and &amp; will be converted to entities.  Binary data (data type
8232      <type>bytea</type>) will be represented in base64 or hex
8233      encoding, depending on the setting of the configuration parameter
8234      <xref linkend="guc-xmlbinary">.  The particular behavior for
8235      individual data types is expected to evolve in order to align the
8236      SQL and PostgreSQL data types with the XML Schema specification,
8237      at which point a more precise description will appear.
8238     </para>
8239    </sect3>
8240  
8241    <sect3>
8242     <title><literal>xmlforest</literal></title>
8243  
8244    <indexterm>
8245     <primary>xmlforest</primary>
8246    </indexterm>
8247  
8248  <synopsis>
8249  <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8250  </synopsis>
8251  
8252     <para>
8253      The <function>xmlforest</function> expression produces an XML
8254      forest (sequence) of elements using the given names and content.
8255     </para>
8256
8257     <para>
8258      Examples:
8259 <screen><![CDATA[
8260 SELECT xmlforest('abc' AS foo, 123 AS bar);
8261
8262           xmlforest
8263 ------------------------------
8264  <foo>abc</foo><bar>123</bar>
8265
8266
8267 SELECT xmlforest(table_name, column_name) FROM information_schema.columns WHERE table_schema = 'pg_catalog';
8268
8269                                          xmlforest
8270 -------------------------------------------------------------------------------------------
8271  <table_name>pg_authid</table_name><column_name>rolname</column_name>
8272  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8273  ...
8274 ]]></screen>
8275
8276      As seen in the second example, the element name can be omitted if
8277      the content value is a column reference, in which case the column
8278      name is used by default.  Otherwise, a name must be specified.
8279     </para>
8280
8281     <para>
8282      Element names that are not valid XML names are escaped as shown
8283      for <function>xmlelement</function> above.  Similarly, content
8284      data is escaped to make valid XML content, unless it is already
8285      of type <type>xml</type>.
8286     </para>
8287
8288     <para>
8289      Note that XML forests are not valid XML documents if they consist
8290      of more than one element.  So it might be useful to wrap
8291      <function>xmlforest</function> expressions in
8292      <function>xmlelement</function>.
8293     </para>
8294    </sect3>
8295  
8296    <sect3>
8297     <title><literal>xmlpi</literal></title>
8298  
8299    <indexterm>
8300     <primary>xmlpi</primary>
8301    </indexterm>
8302  
8303  <synopsis>
8304  <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
8305  </synopsis>
8306  
8307     <para>
8308      The <function>xmlpi</function> expression creates an XML
8309      processing instruction.  The content, if present, must not
8310      contain the character sequence <literal>?&gt;</literal>.
8311     </para>
8312
8313     <para>
8314      Example:
8315 <screen><![CDATA[
8316 SELECT xmlpi(name php, 'echo "hello world";');
8317
8318             xmlpi
8319 -----------------------------
8320  <?php echo "hello world";?>
8321 ]]></screen>
8322     </para>
8323    </sect3>
8324  
8325    <sect3>
8326     <title><literal>xmlroot</literal></title>
8327  
8328    <indexterm>
8329     <primary>xmlroot</primary>
8330    </indexterm>
8331  
8332  <synopsis>
8333  <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable>|no value <optional>, standalone yes|no|no value</optional>)
8334  </synopsis>
8335  
8336     <para>
8337      The <function>xmlroot</function> expression alters the properties
8338      of the root node of an XML value.  If a version is specified,
8339      this replaces the value in the version declaration, if a
8340      standalone value is specified, this replaces the value in the
8341      standalone declaration.
8342     </para>
8343
8344     <para>
8345 <screen><![CDATA[
8346 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'), version '1.0', standalone yes);
8347
8348                 xmlroot
8349 ----------------------------------------
8350  <?xml version="1.0" standalone="yes"?>
8351  <content>abc</content>
8352 ]]></screen>
8353     </para>
8354    </sect3>
8355
8356    <sect3 id="functions-xml-xmlagg">
8357     <title><literal>xmlagg</literal></title>
8358
8359     <indexterm>
8360      <primary>xmlagg</primary>
8361     </indexterm>
8362
8363 <synopsis>
8364 <function>xmlagg</function>(<replaceable>xml</replaceable>)
8365 </synopsis>
8366
8367     <para>
8368      The function <function>xmlagg</function> is, unlike the other
8369      functions described here, an aggregate function.  It concatenates the
8370      input values to the aggregate function call,
8371      like <function>xmlconcat</function> does.
8372      See <xref linkend="functions-aggregate"> for additional information
8373      about aggregate functions.
8374     </para>
8375
8376     <para>
8377      Example:
8378 <screen><![CDATA[
8379 CREATE TABLE test (y int, x xml);
8380 INSERT INTO test VALUES (1, '<foo>abc</foo>');
8381 INSERT INTO test VALUES (2, '<bar/>');
8382 SELECT xmlagg(x) FROM test;
8383         xmlagg
8384 ----------------------
8385  <foo>abc</foo><bar/>
8386 ]]></screen>
8387     </para>
8388
8389     <para>
8390      The influence the order of the concatenation, something like the
8391      following approach to sort the input values can be used:
8392
8393 <screen><![CDATA[
8394 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
8395         xmlagg
8396 ----------------------
8397  <bar/><foo>abc</foo>
8398 ]]></screen>
8399
8400      Again, see <xref linkend="functions-aggregate"> for additional
8401      information.
8402     </para>
8403    </sect3>
8404
8405    <sect3>
8406     <title>XML Predicates</title>
8407
8408     <indexterm>
8409      <primary>IS DOCUMENT</primary>
8410     </indexterm>
8411
8412 <synopsis>
8413 <replaceable>xml</replaceable> IS DOCUMENT
8414 </synopsis>
8415
8416     <para>
8417      The expression <literal>IS DOCUMENT</literal> returns true if the
8418      argument XML value is a proper XML document, false if it is not
8419      (that is, it is a content fragment), or null if the argument is
8420      null.  See <xref linkend="datatype-xml"> about the difference
8421      between documents and content fragments.
8422     </para>
8423    </sect3>
8424   </sect2>
8425
8426   <sect2 id="functions-xml-processing">
8427    <title>Processing XML</title>
8428
8429    <indexterm>
8430     <primary>XPath</primary>
8431    </indexterm>
8432
8433    <para>
8434     To process values of data type <type>xml</type>, PostgreSQL offers
8435     the function <function>xpath</function>, which evaluates XPath 1.0
8436     expressions.
8437    </para>
8438
8439 <synopsis>
8440 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable><optional>, <replaceable>nsarray</replaceable></optional>)
8441 </synopsis>
8442
8443    <para>
8444     The function <function>xpath</function> evaluates the XPath
8445     expression <replaceable>xpath</replaceable> against the XML value
8446     <replaceable>xml</replaceable>.  It returns an array of XML values
8447     corresponding to the node set produced by the XPath expression.
8448    </para>
8449
8450    <para>
8451     The third argument of the function is an array of namespace
8452     mappings.  This array should be a two-dimensional array with the
8453     length of the second axis being equal to 2 (i.e., it should be an
8454     array of arrays, each of which consists of exactly 2 elements).
8455     The first element of each array entry is the namespace name, the
8456     second the namespace URI.
8457    </para>
8458
8459    <para>
8460     Example:
8461 <screen><![CDATA[
8462 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', ARRAY[ARRAY['my', 'http://example.com']]);
8463
8464  xpath  
8465 --------
8466  {test}
8467 (1 row)
8468 ]]></screen>
8469    </para>
8470   </sect2>
8471
8472   <sect2 id="functions-xml-mapping">
8473    <title>Mapping Tables to XML</title>
8474
8475    <indexterm zone="functions-xml-mapping"> 
8476     <primary>XML export</primary>
8477    </indexterm>
8478
8479    <para>
8480     The following functions map the contents of relational tables to
8481     XML values.  They can be thought of as XML export functionality.
8482 <synopsis>
8483 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8484 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
8485 cursor_to_xml(cursor refcursor, count int, nulls boolean, tableforest boolean, targetns text)
8486 </synopsis>
8487     The return type of each function is <type>xml</type>.
8488    </para>
8489
8490    <para>
8491     <function>table_to_xml</function> maps the content of the named
8492     table, passed as parameter <parameter>tbl</parameter>.  The
8493     <type>regclass</type> type accepts strings identifying tables using the
8494     usual notation, including optional schema qualifications and
8495     double quotes.  <function>query_to_xml</function> executes the
8496     query whose text is passed as parameter
8497     <parameter>query</parameter> and maps the result set.
8498     <function>cursor_to_xml</function> fetches the indicated number of
8499     rows from the cursor specified by the parameter
8500     <parameter>cursor</parameter>.  This variant is recommendable if
8501     large tables have to be mapped, because the result value is built
8502     up in memory by each function.
8503    </para>
8504
8505    <para>
8506     If <parameter>tableforest</parameter> is false, then the resulting
8507     XML document looks like this:
8508 <screen><![CDATA[
8509 <tablename>
8510   <row>
8511     <columnname1>data</columnname1>
8512     <columnname2>data</columnname2>
8513   </row>
8514
8515   <row>
8516     ...
8517   </row>
8518
8519   ...
8520 </tablename>
8521 ]]></screen>
8522
8523     If <parameter>tableforest</parameter> is true, the result is an
8524     XML content fragment that looks like this:
8525 <screen><![CDATA[
8526 <tablename>
8527   <columnname1>data</columnname1>
8528   <columnname2>data</columnname2>
8529 </tablename>
8530
8531 <tablename>
8532   ...
8533 </tablename>
8534
8535 ...
8536 ]]></screen>
8537
8538     If no table name is available, that is, when mapping a query or a
8539     cursor, the string <literal>table</literal> is used in the first
8540     format, <literal>row</literal> in the second format.
8541    </para>
8542
8543    <para>
8544     The choice between these formats is up to the user.  The first
8545     format is a proper XML document, which will be important in many
8546     applications.  The second format tends to be more useful in the
8547     <function>cursor_to_xml</function> function if the result values are to be
8548     reassembled into one document later on.  The functions for
8549     producing XML content discussed above, in particular
8550     <function>xmlelement</function>, can be used to alter the results
8551     to taste.
8552    </para>
8553
8554    <para>
8555     The data values are mapped in the same way as described for the
8556     function <function>xmlelement</function> above.
8557    </para>
8558
8559    <para>
8560     The parameter <parameter>nulls</parameter> determines whether null
8561     values should be included in the output.  If true, null values in
8562     columns are represented as
8563 <screen><![CDATA[
8564 <columnname xsi:nil="true"/>
8565 ]]></screen>
8566     where <literal>xsi</literal> is the XML namespace prefix for XML
8567     Schema Instance.  An appropriate namespace declaration will be
8568     added to the result value.  If false, columns containing null
8569     values are simply omitted from the output.
8570    </para>
8571
8572    <para>
8573     The parameter <parameter>targetns</parameter> specifies the
8574     desired XML namespace of the result.  If no particular namespace
8575     is wanted, an empty string should be passed.
8576    </para>
8577
8578    <para>
8579     The following functions return XML Schema documents describing the
8580     mappings made by the data mappings produced by the corresponding
8581     functions above.
8582 <synopsis>
8583 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8584 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8585 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
8586 </synopsis>
8587     It is essential that the same parameters are passed in order to
8588     obtain matching XML data mappings and XML Schema documents.
8589    </para>
8590
8591    <para>
8592     The following functions produce XML data mappings and the
8593     corresponding XML Schema in one document (or forest), linked
8594     together.  They can be useful where self-contained and
8595     self-describing results are wanted.
8596 <synopsis>
8597 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8598 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8599 </synopsis>
8600    </para>
8601
8602    <para>
8603     In addition, the following functions are available to produce
8604     analogous mappings of entire schemas or the entire current
8605     database.
8606 <synopsis>
8607 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
8608 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8609 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8610
8611 database_to_xml(nulls boolean, tableforest boolean, targetns text)
8612 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
8613 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
8614 </synopsis>
8615
8616     Note that these potentially produce a lot of data, which needs to
8617     be built up in memory.  When requesting content mappings of large
8618     schemas or databases, it may be worthwhile to consider mapping the
8619     tables separately instead, possibly even through a cursor.
8620    </para>
8621
8622    <para>
8623     The result of a schema content mapping looks like this:
8624
8625 <screen><![CDATA[
8626 <schemaname>
8627
8628 table1-mapping
8629
8630 table2-mapping
8631
8632 ...
8633
8634 </schemaname>]]></screen>
8635
8636     where the format of a table mapping depends on the
8637     <parameter>tableforest</parameter> parameter as explained above.
8638    </para>
8639
8640    <para>
8641     The result of a database content mapping looks like this:
8642
8643 <screen><![CDATA[
8644 <dbname>
8645
8646 <schema1name>
8647   ...
8648 </schema1name>
8649
8650 <schema2name>
8651   ...
8652 </schema2name>
8653
8654 ...
8655
8656 </dbname>]]></screen>
8657
8658     where the schema mapping is as above.
8659    </para>
8660
8661    <para>
8662     As an example for using the output produced by these functions,
8663     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
8664     converts the output of
8665     <function>table_to_xml_and_xmlschema</function> to an HTML
8666     document containing a tabular rendition of the table data.  In a
8667     similar manner, the result data of these functions can be
8668     converted into other XML-based formats.
8669    </para>
8670
8671    <figure id="xslt-xml-html">
8672     <title>XSLT stylesheet for converting SQL/XML output to HTML</title>
8673 <programlisting><![CDATA[
8674 <?xml version="1.0"?>
8675 <xsl:stylesheet version="1.0"
8676     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
8677     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
8678     xmlns="http://www.w3.org/1999/xhtml"
8679 >
8680
8681   <xsl:output method="xml"
8682       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
8683       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
8684       indent="yes"/>
8685
8686   <xsl:template match="/*">
8687     <xsl:variable name="schema" select="//xsd:schema"/>
8688     <xsl:variable name="tabletypename"
8689                   select="$schema/xsd:element[@name=name(current())]/@type"/>
8690     <xsl:variable name="rowtypename"
8691                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
8692
8693     <html>
8694       <head>
8695         <title><xsl:value-of select="name(current())"/></title>
8696       </head>
8697       <body>
8698         <table>
8699           <tr>
8700             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
8701               <th><xsl:value-of select="."/></th>
8702             </xsl:for-each>
8703           </tr>
8704
8705           <xsl:for-each select="row">
8706             <tr>
8707               <xsl:for-each select="*">
8708                 <td><xsl:value-of select="."/></td>
8709               </xsl:for-each>
8710             </tr>
8711           </xsl:for-each>
8712         </table>
8713       </body>
8714     </html>
8715   </xsl:template>
8716
8717 </xsl:stylesheet>
8718 ]]></programlisting>
8719    </figure>
8720   </sect2>
8721  </sect1>
8722
8723
8724  <sect1 id="functions-sequence">
8725   <title>Sequence Manipulation Functions</title>
8726
8727   <indexterm>
8728    <primary>sequence</primary>
8729   </indexterm>
8730   <indexterm>
8731    <primary>nextval</primary>
8732   </indexterm>
8733   <indexterm>
8734    <primary>currval</primary>
8735   </indexterm>
8736   <indexterm>
8737    <primary>lastval</primary>
8738   </indexterm>
8739   <indexterm>
8740    <primary>setval</primary>
8741   </indexterm>
8742
8743   <para>
8744    This section describes <productname>PostgreSQL</productname>'s
8745    functions for operating on <firstterm>sequence objects</firstterm>.
8746    Sequence objects (also called sequence generators or just
8747    sequences) are special single-row tables created with <xref
8748    linkend="sql-createsequence" endterm="sql-createsequence-title">.
8749    A sequence object is usually used to generate unique identifiers
8750    for rows of a table.  The sequence functions, listed in <xref
8751    linkend="functions-sequence-table">, provide simple, multiuser-safe
8752    methods for obtaining successive sequence values from sequence
8753    objects.
8754   </para>
8755
8756    <table id="functions-sequence-table">
8757     <title>Sequence Functions</title>
8758     <tgroup cols="3">
8759      <thead>
8760       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
8761      </thead>
8762
8763      <tbody>
8764       <row>
8765         <entry><literal><function>currval</function>(<type>regclass</type>)</literal></entry>
8766         <entry><type>bigint</type></entry>
8767         <entry>Return value most recently obtained with
8768         <function>nextval</function> for specified sequence</entry>
8769       </row>
8770       <row>
8771         <entry><literal><function>lastval</function>()</literal></entry>
8772         <entry><type>bigint</type></entry>
8773         <entry>Return value most recently obtained with
8774         <function>nextval</function> for any sequence</entry>
8775       </row>
8776       <row>
8777         <entry><literal><function>nextval</function>(<type>regclass</type>)</literal></entry>
8778         <entry><type>bigint</type></entry>
8779         <entry>Advance sequence and return new value</entry>
8780       </row>
8781       <row>
8782         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>)</literal></entry>
8783         <entry><type>bigint</type></entry>
8784         <entry>Set sequence's current value</entry>
8785       </row>
8786       <row>
8787         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</literal></entry>
8788         <entry><type>bigint</type></entry>
8789         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
8790       </row>
8791      </tbody>
8792     </tgroup>
8793    </table>
8794
8795   <para>
8796    The sequence to be operated on by a sequence-function call is specified by
8797    a <type>regclass</> argument, which is just the OID of the sequence in the
8798    <structname>pg_class</> system catalog.  You do not have to look up the
8799    OID by hand, however, since the <type>regclass</> data type's input
8800    converter will do the work for you.  Just write the sequence name enclosed
8801    in single quotes, so that it looks like a literal constant.  To
8802    achieve some compatibility with the handling of ordinary
8803    <acronym>SQL</acronym> names, the string will be converted to lowercase
8804    unless it contains double quotes around the sequence name.  Thus:
8805 <programlisting>
8806 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
8807 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
8808 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
8809 </programlisting>
8810    The sequence name can be schema-qualified if necessary:
8811 <programlisting>
8812 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
8813 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
8814 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
8815 </programlisting>
8816    See <xref linkend="datatype-oid"> for more information about
8817    <type>regclass</>.
8818   </para>
8819
8820   <note>
8821    <para>
8822     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
8823     sequence functions were of type <type>text</>, not <type>regclass</>, and
8824     the above-described conversion from a text string to an OID value would
8825     happen at run time during each call.  For backwards compatibility, this
8826     facility still exists, but internally it is now handled as an implicit
8827     coercion from <type>text</> to <type>regclass</> before the function is
8828     invoked.
8829    </para>
8830
8831    <para>
8832     When you write the argument of a sequence function as an unadorned
8833     literal string, it becomes a constant of type <type>regclass</>.
8834     Since this is really just an OID, it will track the originally
8835     identified sequence despite later renaming, schema reassignment,
8836     etc.  This <quote>early binding</> behavior is usually desirable for
8837     sequence references in column defaults and views.  But sometimes you will
8838     want <quote>late binding</> where the sequence reference is resolved
8839     at run time.  To get late-binding behavior, force the constant to be
8840     stored as a <type>text</> constant instead of <type>regclass</>:
8841 <programlisting>
8842 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
8843 </programlisting>
8844     Note that late binding was the only behavior supported in
8845     <productname>PostgreSQL</productname> releases before 8.1, so you
8846     might need to do this to preserve the semantics of old applications.
8847    </para>
8848
8849    <para>
8850     Of course, the argument of a sequence function can be an expression
8851     as well as a constant.  If it is a text expression then the implicit
8852     coercion will result in a run-time lookup.
8853    </para>
8854   </note>
8855
8856   <para>
8857    The available sequence functions are:
8858
8859     <variablelist>
8860      <varlistentry>
8861       <term><function>nextval</function></term>
8862       <listitem>
8863        <para>
8864         Advance the sequence object to its next value and return that
8865         value.  This is done atomically: even if multiple sessions
8866         execute <function>nextval</function> concurrently, each will safely receive
8867         a distinct sequence value.
8868        </para>
8869       </listitem>
8870      </varlistentry>
8871
8872      <varlistentry>
8873       <term><function>currval</function></term>
8874       <listitem>
8875        <para>
8876         Return the value most recently obtained by <function>nextval</function>
8877         for this sequence in the current session.  (An error is
8878         reported if <function>nextval</function> has never been called for this
8879         sequence in this session.)  Notice that because this is returning
8880         a session-local value, it gives a predictable answer whether or not
8881         other sessions have executed <function>nextval</function> since the
8882         current session did.
8883        </para>
8884       </listitem>
8885      </varlistentry>
8886
8887      <varlistentry>
8888       <term><function>lastval</function></term>
8889       <listitem>
8890        <para>
8891         Return the value most recently returned by
8892         <function>nextval</> in the current session. This function is
8893         identical to <function>currval</function>, except that instead
8894         of taking the sequence name as an argument it fetches the
8895         value of the last sequence that <function>nextval</function>
8896         was used on in the current session. It is an error to call
8897         <function>lastval</function> if <function>nextval</function>
8898         has not yet been called in the current session.
8899        </para>
8900       </listitem>
8901      </varlistentry>
8902
8903      <varlistentry>
8904       <term><function>setval</function></term>
8905       <listitem>
8906        <para>
8907         Reset the sequence object's counter value.  The two-parameter
8908         form sets the sequence's <literal>last_value</literal> field to the
8909         specified value and sets its <literal>is_called</literal> field to
8910         <literal>true</literal>, meaning that the next
8911         <function>nextval</function> will advance the sequence before
8912         returning a value.  The value reported by <function>currval</> is
8913         also set to the specified value.  In the three-parameter form,
8914         <literal>is_called</literal> can be set either <literal>true</literal>
8915         or <literal>false</literal>.  <literal>true</> has the same effect as
8916         the two-parameter form. If it's set to <literal>false</literal>, the
8917         next <function>nextval</function> will return exactly the specified
8918         value, and sequence advancement commences with the following
8919         <function>nextval</function>.  Furthermore, the value reported by
8920         <function>currval</> is not changed in this case (this is a change
8921         from pre-8.3 behavior).  For example,
8922
8923 <screen>
8924 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
8925 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
8926 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
8927 </screen>
8928
8929         The result returned by <function>setval</function> is just the value of its
8930         second argument.
8931        </para>
8932       </listitem>
8933      </varlistentry>
8934     </variablelist>
8935   </para>
8936
8937   <para>
8938    If a sequence object has been created with default parameters,
8939    <function>nextval</function> calls on it will return successive values
8940    beginning with 1.  Other behaviors can be obtained by using
8941    special parameters in the <xref linkend="sql-createsequence" endterm="sql-createsequence-title"> command;
8942    see its command reference page for more information.
8943   </para>
8944
8945   <important>
8946    <para>
8947     To avoid blocking of concurrent transactions that obtain numbers from the
8948     same sequence, a <function>nextval</function> operation is never rolled back;
8949     that is, once a value has been fetched it is considered used, even if the
8950     transaction that did the <function>nextval</function> later aborts.  This means
8951     that aborted transactions might leave unused <quote>holes</quote> in the
8952     sequence of assigned values.  <function>setval</function> operations are never
8953     rolled back, either.
8954    </para>
8955   </important>
8956
8957  </sect1>
8958
8959
8960  <sect1 id="functions-conditional">
8961   <title>Conditional Expressions</title>
8962
8963   <indexterm>
8964    <primary>CASE</primary>
8965   </indexterm>
8966
8967   <indexterm>
8968    <primary>conditional expression</primary>
8969   </indexterm>
8970
8971   <para>
8972    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
8973    available in <productname>PostgreSQL</productname>.
8974   </para>
8975
8976   <tip>
8977    <para>
8978     If your needs go beyond the capabilities of these conditional
8979     expressions you might want to consider writing a stored procedure
8980     in a more expressive programming language.
8981    </para>
8982   </tip>
8983
8984   <sect2>
8985    <title><literal>CASE</></title>
8986
8987   <para>
8988    The <acronym>SQL</acronym> <token>CASE</token> expression is a
8989    generic conditional expression, similar to if/else statements in
8990    other languages:
8991
8992 <synopsis>
8993 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
8994      <optional>WHEN ...</optional>
8995      <optional>ELSE <replaceable>result</replaceable></optional>
8996 END
8997 </synopsis>
8998
8999    <token>CASE</token> clauses can be used wherever
9000    an expression is valid.  <replaceable>condition</replaceable> is an
9001    expression that returns a <type>boolean</type> result.  If the result is true
9002    then the value of the <token>CASE</token> expression is the
9003    <replaceable>result</replaceable> that follows the condition.  If the result is false any
9004    subsequent <token>WHEN</token> clauses are searched in the same
9005    manner.  If no <token>WHEN</token>
9006    <replaceable>condition</replaceable> is true then the value of the
9007    case expression is the <replaceable>result</replaceable> in the
9008    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
9009    omitted and no condition matches, the result is null.
9010   </para>
9011
9012    <para>
9013     An example:
9014 <screen>
9015 SELECT * FROM test;
9016
9017  a
9018 ---
9019  1
9020  2
9021  3
9022
9023
9024 SELECT a,
9025        CASE WHEN a=1 THEN 'one'
9026             WHEN a=2 THEN 'two'
9027             ELSE 'other'
9028        END
9029     FROM test;
9030
9031  a | case
9032 ---+-------
9033  1 | one
9034  2 | two
9035  3 | other
9036 </screen>
9037    </para>
9038
9039   <para>
9040    The data types of all the <replaceable>result</replaceable>
9041    expressions must be convertible to a single output type.
9042    See <xref linkend="typeconv-union-case"> for more detail.
9043   </para>
9044
9045   <para>
9046    The following <quote>simple</quote> <token>CASE</token> expression is a
9047    specialized variant of the general form above:
9048
9049 <synopsis>
9050 CASE <replaceable>expression</replaceable>
9051     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
9052     <optional>WHEN ...</optional>
9053     <optional>ELSE <replaceable>result</replaceable></optional>
9054 END
9055 </synopsis>
9056
9057    The
9058    <replaceable>expression</replaceable> is computed and compared to
9059    all the <replaceable>value</replaceable> specifications in the
9060    <token>WHEN</token> clauses until one is found that is equal.  If
9061    no match is found, the <replaceable>result</replaceable> in the
9062    <token>ELSE</token> clause (or a null value) is returned.  This is similar
9063    to the <function>switch</function> statement in C.
9064   </para>
9065
9066    <para>
9067     The example above can be written using the simple
9068     <token>CASE</token> syntax:
9069 <screen>
9070 SELECT a,
9071        CASE a WHEN 1 THEN 'one'
9072               WHEN 2 THEN 'two'
9073               ELSE 'other'
9074        END
9075     FROM test;
9076
9077  a | case
9078 ---+-------
9079  1 | one
9080  2 | two
9081  3 | other
9082 </screen>
9083    </para>
9084
9085    <para>
9086     A <token>CASE</token> expression does not evaluate any subexpressions
9087     that are not needed to determine the result.  For example, this is a
9088     possible way of avoiding a division-by-zero failure:
9089 <programlisting>
9090 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
9091 </programlisting>
9092    </para>
9093   </sect2>
9094
9095   <sect2>
9096    <title><literal>COALESCE</></title>
9097
9098   <indexterm>
9099    <primary>COALESCE</primary>
9100   </indexterm>
9101
9102   <indexterm>
9103    <primary>NVL</primary>
9104   </indexterm>
9105
9106   <indexterm>
9107    <primary>IFNULL</primary>
9108   </indexterm>
9109
9110 <synopsis>
9111 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9112 </synopsis>
9113
9114   <para>
9115    The <function>COALESCE</function> function returns the first of its
9116    arguments that is not null.  Null is returned only if all arguments
9117    are null.  It is often used to substitute a default value for 
9118    null values when data is retrieved for display, for example:
9119 <programlisting>
9120 SELECT COALESCE(description, short_description, '(none)') ...
9121 </programlisting>
9122   </para>
9123
9124    <para>
9125     Like a <token>CASE</token> expression, <function>COALESCE</function> will
9126     not evaluate arguments that are not needed to determine the result;
9127     that is, arguments to the right of the first non-null argument are
9128     not evaluated.  This SQL-standard function provides capabilities similar
9129     to <function>NVL</> and <function>IFNULL</>, which are used in some other
9130     database systems.
9131    </para>
9132   </sect2>
9133
9134   <sect2>
9135    <title><literal>NULLIF</></title>
9136
9137   <indexterm>
9138    <primary>NULLIF</primary>
9139   </indexterm>
9140
9141 <synopsis>
9142 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
9143 </synopsis>
9144
9145   <para>
9146    The <function>NULLIF</function> function returns a null value if
9147    <replaceable>value1</replaceable> and <replaceable>value2</replaceable>
9148    are equal;  otherwise it returns <replaceable>value1</replaceable>.
9149    This can be used to perform the inverse operation of the
9150    <function>COALESCE</function> example given above:
9151 <programlisting>
9152 SELECT NULLIF(value, '(none)') ...
9153 </programlisting>
9154   </para>
9155   <para>
9156    If <replaceable>value1</replaceable> is <literal>(none)</>, return a null,
9157    otherwise return <replaceable>value1</replaceable>.
9158   </para>
9159
9160   </sect2>
9161
9162   <sect2>
9163    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
9164
9165   <indexterm>
9166    <primary>GREATEST</primary>
9167   </indexterm>
9168   <indexterm>
9169    <primary>LEAST</primary>
9170   </indexterm>
9171
9172 <synopsis>
9173 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9174 </synopsis>
9175 <synopsis>
9176 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9177 </synopsis>
9178
9179    <para>
9180     The <function>GREATEST</> and <function>LEAST</> functions select the
9181     largest or smallest value from a list of any number of expressions.
9182     The expressions must all be convertible to a common data type, which
9183     will be the type of the result
9184     (see <xref linkend="typeconv-union-case"> for details).  NULL values
9185     in the list are ignored.  The result will be NULL only if all the
9186     expressions evaluate to NULL.
9187    </para>
9188
9189    <para>
9190     Note that <function>GREATEST</> and <function>LEAST</> are not in
9191     the SQL standard, but are a common extension.  Some other databases
9192     make them return NULL if any argument is NULL, rather than only when
9193     all are NULL.
9194    </para>
9195   </sect2>
9196  </sect1>
9197
9198  <sect1 id="functions-array">
9199   <title>Array Functions and Operators</title>
9200
9201   <para>
9202    <xref linkend="array-operators-table"> shows the operators
9203    available for array types.
9204   </para>
9205
9206     <table id="array-operators-table">
9207      <title>Array Operators</title>
9208      <tgroup cols="4">
9209       <thead>
9210        <row>
9211         <entry>Operator</entry>
9212         <entry>Description</entry>
9213         <entry>Example</entry>
9214         <entry>Result</entry>
9215        </row>
9216       </thead>
9217       <tbody>
9218        <row>
9219         <entry> <literal>=</literal> </entry>
9220         <entry>equal</entry>
9221         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
9222         <entry><literal>t</literal></entry>
9223        </row>
9224
9225        <row>
9226         <entry> <literal>&lt;&gt;</literal> </entry>
9227         <entry>not equal</entry>
9228         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
9229         <entry><literal>t</literal></entry>
9230        </row>
9231
9232        <row>
9233         <entry> <literal>&lt;</literal> </entry>
9234         <entry>less than</entry>
9235         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
9236         <entry><literal>t</literal></entry>
9237        </row>
9238
9239        <row>
9240         <entry> <literal>&gt;</literal> </entry>
9241         <entry>greater than</entry>
9242         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
9243         <entry><literal>t</literal></entry>
9244        </row>
9245
9246        <row>
9247         <entry> <literal>&lt;=</literal> </entry>
9248         <entry>less than or equal</entry>
9249         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
9250         <entry><literal>t</literal></entry>
9251        </row>
9252
9253        <row>
9254         <entry> <literal>&gt;=</literal> </entry>
9255         <entry>greater than or equal</entry>
9256         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
9257         <entry><literal>t</literal></entry>
9258        </row>
9259
9260        <row>
9261         <entry> <literal>@&gt;</literal> </entry>
9262         <entry>contains</entry>
9263         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
9264         <entry><literal>t</literal></entry>
9265        </row>
9266
9267        <row>
9268         <entry> <literal>&lt;@</literal> </entry>
9269         <entry>is contained by</entry>
9270         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
9271         <entry><literal>t</literal></entry>
9272        </row>
9273
9274        <row>
9275         <entry> <literal>&amp;&amp;</literal> </entry>
9276         <entry>overlap (have elements in common)</entry>
9277         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
9278         <entry><literal>t</literal></entry>
9279        </row>
9280
9281        <row>
9282         <entry> <literal>||</literal> </entry>
9283         <entry>array-to-array concatenation</entry>
9284         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
9285         <entry><literal>{1,2,3,4,5,6}</literal></entry>
9286        </row>
9287
9288        <row>
9289         <entry> <literal>||</literal> </entry>
9290         <entry>array-to-array concatenation</entry>
9291         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
9292         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
9293        </row>
9294
9295        <row>
9296         <entry> <literal>||</literal> </entry>
9297         <entry>element-to-array concatenation</entry>
9298         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
9299         <entry><literal>{3,4,5,6}</literal></entry>
9300        </row>
9301
9302        <row>
9303         <entry> <literal>||</literal> </entry>
9304         <entry>array-to-element concatenation</entry>
9305         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
9306         <entry><literal>{4,5,6,7}</literal></entry>
9307        </row>
9308       </tbody>
9309      </tgroup>
9310     </table>
9311
9312   <para>
9313    Array comparisons compare the array contents element-by-element,
9314    using the default B-Tree comparison function for the element data type.
9315    In multidimensional arrays the elements are visited in row-major order
9316    (last subscript varies most rapidly).
9317    If the contents of two arrays are equal but the dimensionality is
9318    different, the first difference in the dimensionality information
9319    determines the sort order.  (This is a change from versions of
9320    <productname>PostgreSQL</> prior to 8.2: older versions would claim
9321    that two arrays with the same contents were equal, even if the
9322    number of dimensions or subscript ranges were different.)
9323   </para>
9324
9325   <para>
9326    See <xref linkend="arrays"> for more details about array operator
9327    behavior.
9328   </para>
9329
9330   <para>
9331    <xref linkend="array-functions-table"> shows the functions
9332    available for use with array types. See <xref linkend="arrays">
9333    for more discussion and examples of the use of these functions.
9334   </para>
9335
9336     <table id="array-functions-table">
9337      <title>Array Functions</title>
9338      <tgroup cols="5">
9339       <thead>
9340        <row>
9341         <entry>Function</entry>
9342         <entry>Return Type</entry>
9343         <entry>Description</entry>
9344         <entry>Example</entry>
9345         <entry>Result</entry>
9346        </row>
9347       </thead>
9348       <tbody>
9349        <row>
9350         <entry>
9351          <literal>
9352           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
9353          </literal>
9354         </entry>
9355         <entry><type>anyarray</type></entry>
9356         <entry>append an element to the end of an array</entry>
9357         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
9358         <entry><literal>{1,2,3}</literal></entry>
9359        </row>
9360        <row>
9361         <entry>
9362          <literal>
9363           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
9364          </literal>
9365         </entry>
9366         <entry><type>anyarray</type></entry>
9367         <entry>concatenate two arrays</entry>
9368         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
9369         <entry><literal>{1,2,3,4,5}</literal></entry>
9370        </row>
9371        <row>
9372         <entry>
9373          <literal>
9374           <function>array_ndims</function>(<type>anyarray</type>)
9375          </literal>
9376         </entry>
9377         <entry><type>int</type></entry>
9378         <entry>returns the number of dimensions of the array</entry>
9379         <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9380         <entry><literal>2</literal></entry>
9381        </row>
9382        <row>
9383         <entry>
9384          <literal>
9385           <function>array_dims</function>(<type>anyarray</type>)
9386          </literal>
9387         </entry>
9388         <entry><type>text</type></entry>
9389         <entry>returns a text representation of array's dimensions</entry>
9390         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9391         <entry><literal>[1:2][1:3]</literal></entry>
9392        </row>
9393        <row>
9394         <entry>
9395          <literal>
9396           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
9397           <optional>, <type>int[]</type></optional>)
9398          </literal>
9399         </entry>
9400         <entry><type>anyarray</type></entry>
9401         <entry>returns an array initialized with supplied value and
9402          dimensions, optionally with lower bounds other than 1</entry>
9403         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
9404         <entry><literal>[2:4]={7,7,7}</literal></entry>
9405        </row>
9406        <row>
9407         <entry>
9408          <literal>
9409           <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
9410          </literal>
9411         </entry>
9412         <entry><type>int</type></entry>
9413         <entry>returns the length of the requested array dimension</entry>
9414         <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
9415         <entry><literal>3</literal></entry>
9416        </row>
9417        <row>
9418         <entry>
9419          <literal>
9420           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
9421          </literal>
9422         </entry>
9423         <entry><type>int</type></entry>
9424         <entry>returns lower bound of the requested array dimension</entry>
9425         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
9426         <entry><literal>0</literal></entry>
9427        </row>
9428        <row>
9429         <entry>
9430          <literal>
9431           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
9432          </literal>
9433         </entry>
9434         <entry><type>anyarray</type></entry>
9435         <entry>append an element to the beginning of an array</entry>
9436         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
9437         <entry><literal>{1,2,3}</literal></entry>
9438        </row>
9439        <row>
9440         <entry>
9441          <literal>
9442           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type>)
9443          </literal>
9444         </entry>
9445         <entry><type>text</type></entry>
9446         <entry>concatenates array elements using provided delimiter</entry>
9447         <entry><literal>array_to_string(ARRAY[1, 2, 3], '~^~')</literal></entry>
9448         <entry><literal>1~^~2~^~3</literal></entry>
9449        </row>
9450        <row>
9451         <entry>
9452          <literal>
9453           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
9454          </literal>
9455         </entry>
9456         <entry><type>int</type></entry>
9457         <entry>returns upper bound of the requested array dimension</entry>
9458         <entry><literal>array_upper(ARRAY[1,2,3,4], 1)</literal></entry>
9459         <entry><literal>4</literal></entry>
9460        </row>
9461        <row>
9462         <entry>
9463          <literal>
9464           <function>cardinality</function>(<type>anyarray</type>)
9465          </literal>
9466         </entry>
9467         <entry><type>int</type></entry>
9468         <entry>returns the length of the first dimension of the array
9469         (special case of <function>array_length</function> for SQL
9470         compatibility)</entry>
9471         <entry><literal>cardinality(array[1,2,3])</literal></entry>
9472         <entry><literal>3</literal></entry>
9473        </row>
9474        <row>
9475         <entry>
9476          <literal>
9477           <function>string_to_array</function>(<type>text</type>, <type>text</type>)
9478          </literal>
9479         </entry>
9480         <entry><type>text[]</type></entry>
9481         <entry>splits string into array elements using provided delimiter</entry>
9482         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~')</literal></entry>
9483         <entry><literal>{xx,yy,zz}</literal></entry>
9484        </row>
9485       </tbody>
9486      </tgroup>
9487     </table>
9488
9489    <para>
9490     See also <xref linkend="functions-aggregate"> about the aggregate
9491     function <function>array_agg</function> for use with arrays.
9492    </para>
9493   </sect1>
9494
9495  <sect1 id="functions-aggregate">
9496   <title>Aggregate Functions</title>
9497
9498   <indexterm zone="functions-aggregate">
9499    <primary>aggregate function</primary>
9500    <secondary>built-in</secondary>
9501   </indexterm>
9502
9503   <para>
9504    <firstterm>Aggregate functions</firstterm> compute a single result
9505    value from a set of input values.  The built-in aggregate functions
9506    are listed in
9507    <xref linkend="functions-aggregate-table"> and
9508    <xref linkend="functions-aggregate-statistics-table">.
9509    The special syntax considerations for aggregate
9510    functions are explained in <xref linkend="syntax-aggregates">.
9511    Consult <xref linkend="tutorial-agg"> for additional introductory
9512    information.
9513   </para>
9514
9515   <table id="functions-aggregate-table">
9516    <title>General-Purpose Aggregate Functions</title>
9517
9518    <tgroup cols="4">
9519     <thead>
9520      <row>
9521       <entry>Function</entry>
9522       <entry>Argument Type</entry>
9523       <entry>Return Type</entry>
9524       <entry>Description</entry>
9525      </row>
9526     </thead>
9527
9528     <tbody>
9529      <row>
9530       <entry>
9531        <indexterm>
9532         <primary>array_agg</primary>
9533        </indexterm>
9534        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
9535       </entry>
9536       <entry>
9537        any
9538       </entry>
9539       <entry>
9540        array of the argument type
9541       </entry>
9542       <entry>input values concatenated into an array</entry>
9543      </row>
9544
9545      <row>
9546       <entry>
9547        <indexterm>
9548         <primary>average</primary>
9549        </indexterm>
9550        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
9551       </entry>
9552       <entry>
9553        <type>smallint</type>, <type>int</type>,
9554        <type>bigint</type>, <type>real</type>, <type>double
9555        precision</type>, <type>numeric</type>, or <type>interval</type>
9556       </entry>
9557       <entry>
9558        <type>numeric</type> for any integer type argument,
9559        <type>double precision</type> for a floating-point argument,
9560        otherwise the same as the argument data type
9561       </entry>
9562       <entry>the average (arithmetic mean) of all input values</entry>
9563      </row>
9564
9565      <row>
9566       <entry>
9567        <indexterm>
9568         <primary>bit_and</primary>
9569        </indexterm>
9570        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
9571       </entry>
9572       <entry>
9573        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9574        <type>bit</type>
9575       </entry>
9576       <entry>
9577         same as argument data type
9578       </entry>
9579       <entry>the bitwise AND of all non-null input values, or null if none</entry>
9580      </row>
9581
9582      <row>
9583       <entry>
9584        <indexterm>
9585         <primary>bit_or</primary>
9586        </indexterm>
9587        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
9588       </entry>
9589       <entry>
9590        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9591        <type>bit</type>
9592       </entry>
9593       <entry>
9594         same as argument data type
9595       </entry>
9596       <entry>the bitwise OR of all non-null input values, or null if none</entry>
9597      </row>
9598
9599      <row>
9600       <entry>
9601        <indexterm>
9602         <primary>bool_and</primary>
9603        </indexterm>
9604        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
9605       </entry>
9606       <entry>
9607        <type>bool</type>
9608       </entry>
9609       <entry>
9610        <type>bool</type>
9611       </entry>
9612       <entry>true if all input values are true, otherwise false</entry>
9613      </row>
9614
9615      <row>
9616       <entry>
9617        <indexterm>
9618         <primary>bool_or</primary>
9619        </indexterm>
9620        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
9621       </entry>
9622       <entry>
9623        <type>bool</type>
9624       </entry>
9625       <entry>
9626        <type>bool</type>
9627       </entry>
9628       <entry>true if at least one input value is true, otherwise false</entry>
9629      </row>
9630
9631      <row>
9632       <entry><function>count(*)</function></entry>
9633       <entry></entry>
9634       <entry><type>bigint</type></entry>
9635       <entry>number of input rows</entry>
9636      </row>
9637
9638      <row>
9639       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
9640       <entry>any</entry>
9641       <entry><type>bigint</type></entry>
9642       <entry>
9643        number of input rows for which the value of <replaceable
9644        class="parameter">expression</replaceable> is not null
9645       </entry>
9646      </row>
9647
9648      <row>
9649       <entry>
9650        <indexterm>
9651         <primary>every</primary>
9652        </indexterm>
9653        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
9654       </entry>
9655       <entry>
9656        <type>bool</type>
9657       </entry>
9658       <entry>
9659        <type>bool</type>
9660       </entry>
9661       <entry>equivalent to <function>bool_and</function></entry>
9662      </row>
9663
9664      <row>
9665       <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
9666       <entry>any array, numeric, string, or date/time type</entry>
9667       <entry>same as argument type</entry>
9668       <entry>
9669        maximum value of <replaceable
9670        class="parameter">expression</replaceable> across all input
9671        values
9672       </entry>
9673      </row>
9674
9675      <row>
9676       <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
9677       <entry>any array, numeric, string, or date/time type</entry>
9678       <entry>same as argument type</entry>
9679       <entry>
9680        minimum value of <replaceable
9681        class="parameter">expression</replaceable> across all input
9682        values
9683       </entry>
9684      </row>
9685
9686      <row>
9687       <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></entry>
9688       <entry>
9689        <type>smallint</type>, <type>int</type>,
9690        <type>bigint</type>, <type>real</type>, <type>double
9691        precision</type>, <type>numeric</type>, or
9692        <type>interval</type>
9693       </entry>
9694       <entry>
9695        <type>bigint</type> for <type>smallint</type> or
9696        <type>int</type> arguments, <type>numeric</type> for
9697        <type>bigint</type> arguments, <type>double precision</type>
9698        for floating-point arguments, otherwise the same as the
9699        argument data type
9700       </entry>
9701       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
9702      </row>
9703
9704      <row>
9705       <entry>
9706        <indexterm>
9707         <primary>xmlagg</primary>
9708        </indexterm>
9709        <function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
9710       </entry>
9711       <entry>
9712        <type>xml</type>
9713       </entry>
9714       <entry>
9715        <type>xml</type>
9716       </entry>
9717       <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
9718      </row>
9719     </tbody>
9720    </tgroup>
9721   </table>
9722
9723   <para>
9724    It should be noted that except for <function>count</function>,
9725    these functions return a null value when no rows are selected.  In
9726    particular, <function>sum</function> of no rows returns null, not
9727    zero as one might expect, and <function>array_agg</function>
9728    returns null rather than an empty array when there are no input
9729    rows.  The <function>coalesce</function> function can be used to
9730    substitute zero or an empty array for null when necessary.
9731   </para>
9732
9733   <note>
9734     <indexterm>
9735       <primary>ANY</primary>
9736     </indexterm>
9737     <indexterm>
9738       <primary>SOME</primary>
9739     </indexterm>
9740     <para>
9741       Boolean aggregates <function>bool_and</function> and 
9742       <function>bool_or</function> correspond to standard SQL aggregates
9743       <function>every</function> and <function>any</function> or
9744       <function>some</function>. 
9745       As for <function>any</function> and <function>some</function>, 
9746       it seems that there is an ambiguity built into the standard syntax:
9747 <programlisting>
9748 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
9749 </programlisting>
9750       Here <function>ANY</function> can be considered both as leading
9751       to a subquery or as an aggregate if the select expression returns 1 row.
9752       Thus the standard name cannot be given to these aggregates.
9753     </para>
9754   </note>
9755
9756   <note>
9757    <para>
9758     Users accustomed to working with other SQL database management
9759     systems might be surprised by the performance of the
9760     <function>count</function> aggregate when it is applied to the
9761     entire table. A query like:
9762 <programlisting>
9763 SELECT count(*) FROM sometable;
9764 </programlisting>
9765     will be executed by <productname>PostgreSQL</productname> using a
9766     sequential scan of the entire table.
9767    </para>
9768   </note>
9769
9770   <para>
9771    The aggregate functions <function>array_agg</function>
9772    and <function>xmlagg</function>, as well as similar user-defined
9773    aggregate functions, produce meaningfully different result values
9774    depending on the order of the input values.  In the current
9775    implementation, the order of the concatenation is in principle
9776    undefined.  Making the input values to be sorted in some other way
9777    will usually work, however.  For example:
9778
9779 <screen><![CDATA[
9780 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
9781 ]]></screen>
9782
9783    But this approach is not guaranteed to work in all situations, and
9784    it is not strictly SQL-conforming.  A future version of PostgreSQL
9785    might provide an additional feature to control the order in a
9786    better-defined way (<literal>xmlagg(expr ORDER BY expr, expr,
9787    ...</literal>).
9788   </para>
9789
9790   <para>
9791    <xref linkend="functions-aggregate-statistics-table"> shows
9792    aggregate functions typically used in statistical analysis.
9793    (These are separated out merely to avoid cluttering the listing
9794    of more-commonly-used aggregates.)  Where the description mentions
9795    <replaceable class="parameter">N</replaceable>, it means the
9796    number of input rows for which all the input expressions are non-null.
9797    In all cases, null is returned if the computation is meaningless,
9798    for example when <replaceable class="parameter">N</replaceable> is zero.
9799   </para>
9800
9801   <indexterm>
9802    <primary>statistics</primary>
9803   </indexterm>
9804   <indexterm>
9805    <primary>linear regression</primary>
9806   </indexterm>
9807
9808   <table id="functions-aggregate-statistics-table">
9809    <title>Aggregate Functions for Statistics</title>
9810
9811    <tgroup cols="4">
9812     <thead>
9813      <row>
9814       <entry>Function</entry>
9815       <entry>Argument Type</entry>
9816       <entry>Return Type</entry>
9817       <entry>Description</entry>
9818      </row>
9819     </thead>
9820
9821     <tbody>
9822
9823      <row>
9824       <entry>
9825        <indexterm>
9826         <primary>correlation</primary>
9827        </indexterm>
9828        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9829       </entry>
9830       <entry>
9831        <type>double precision</type>
9832       </entry>
9833       <entry>
9834        <type>double precision</type>
9835       </entry>
9836       <entry>correlation coefficient</entry>
9837      </row>
9838
9839      <row>
9840       <entry>
9841        <indexterm>
9842         <primary>covariance</primary>
9843         <secondary>population</secondary>
9844        </indexterm>
9845        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9846       </entry>
9847       <entry>
9848        <type>double precision</type>
9849       </entry>
9850       <entry>
9851        <type>double precision</type>
9852       </entry>
9853       <entry>population covariance</entry>
9854      </row>
9855
9856      <row>
9857       <entry>
9858        <indexterm>
9859         <primary>covariance</primary>
9860         <secondary>sample</secondary>
9861        </indexterm>
9862        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9863       </entry>
9864       <entry>
9865        <type>double precision</type>
9866       </entry>
9867       <entry>
9868        <type>double precision</type>
9869       </entry>
9870       <entry>sample covariance</entry>
9871      </row>
9872
9873      <row>
9874       <entry>
9875        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9876       </entry>
9877       <entry>
9878        <type>double precision</type>
9879       </entry>
9880       <entry>
9881        <type>double precision</type>
9882       </entry>
9883       <entry>average of the independent variable
9884       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9885      </row>
9886
9887      <row>
9888       <entry>
9889        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9890       </entry>
9891       <entry>
9892        <type>double precision</type>
9893       </entry>
9894       <entry>
9895        <type>double precision</type>
9896       </entry>
9897       <entry>average of the dependent variable
9898       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9899      </row>
9900
9901      <row>
9902       <entry>
9903        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9904       </entry>
9905       <entry>
9906        <type>double precision</type>
9907       </entry>
9908       <entry>
9909        <type>bigint</type>
9910       </entry>
9911       <entry>number of input rows in which both expressions are nonnull</entry>
9912      </row>
9913
9914      <row>
9915       <entry>
9916        <indexterm>
9917         <primary>regression intercept</primary>
9918        </indexterm>
9919        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9920       </entry>
9921       <entry>
9922        <type>double precision</type>
9923       </entry>
9924       <entry>
9925        <type>double precision</type>
9926       </entry>
9927       <entry>y-intercept of the least-squares-fit linear equation
9928       determined by the (<replaceable
9929       class="parameter">X</replaceable>, <replaceable
9930       class="parameter">Y</replaceable>) pairs</entry>
9931      </row>
9932
9933      <row>
9934       <entry>
9935        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9936       </entry>
9937       <entry>
9938        <type>double precision</type>
9939       </entry>
9940       <entry>
9941        <type>double precision</type>
9942       </entry>
9943       <entry>square of the correlation coefficient</entry>
9944      </row>
9945
9946      <row>
9947       <entry>
9948        <indexterm>
9949         <primary>regression slope</primary>
9950        </indexterm>
9951        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9952       </entry>
9953       <entry>
9954        <type>double precision</type>
9955       </entry>
9956       <entry>
9957        <type>double precision</type>
9958       </entry>
9959       <entry>slope of the least-squares-fit linear equation determined
9960       by the (<replaceable class="parameter">X</replaceable>,
9961       <replaceable class="parameter">Y</replaceable>) pairs</entry>
9962      </row>
9963
9964      <row>
9965       <entry>
9966        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9967       </entry>
9968       <entry>
9969        <type>double precision</type>
9970       </entry>
9971       <entry>
9972        <type>double precision</type>
9973       </entry>
9974       <entry><literal>sum(<replaceable
9975       class="parameter">X</replaceable>^2) - sum(<replaceable
9976       class="parameter">X</replaceable>)^2/<replaceable
9977       class="parameter">N</replaceable></literal> (<quote>sum of
9978       squares</quote> of the independent variable)</entry>
9979      </row>
9980
9981      <row>
9982       <entry>
9983        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9984       </entry>
9985       <entry>
9986        <type>double precision</type>
9987       </entry>
9988       <entry>
9989        <type>double precision</type>
9990       </entry>
9991       <entry><literal>sum(<replaceable
9992       class="parameter">X</replaceable>*<replaceable
9993       class="parameter">Y</replaceable>) - sum(<replaceable
9994       class="parameter">X</replaceable>) * sum(<replaceable
9995       class="parameter">Y</replaceable>)/<replaceable
9996       class="parameter">N</replaceable></literal> (<quote>sum of
9997       products</quote> of independent times dependent
9998       variable)</entry>
9999      </row>
10000
10001      <row>
10002       <entry>
10003        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10004       </entry>
10005       <entry>
10006        <type>double precision</type>
10007       </entry>
10008       <entry>
10009        <type>double precision</type>
10010       </entry>
10011       <entry><literal>sum(<replaceable
10012       class="parameter">Y</replaceable>^2) - sum(<replaceable
10013       class="parameter">Y</replaceable>)^2/<replaceable
10014       class="parameter">N</replaceable></literal> (<quote>sum of
10015       squares</quote> of the dependent variable)</entry>
10016      </row>
10017
10018      <row>
10019       <entry>
10020        <indexterm>
10021         <primary>standard deviation</primary>
10022        </indexterm>
10023        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
10024       </entry>
10025       <entry>
10026        <type>smallint</type>, <type>int</type>,
10027        <type>bigint</type>, <type>real</type>, <type>double
10028        precision</type>, or <type>numeric</type>
10029       </entry>
10030       <entry>
10031        <type>double precision</type> for floating-point arguments,
10032        otherwise <type>numeric</type>
10033       </entry>
10034       <entry>historical alias for <function>stddev_samp</function></entry>
10035      </row>
10036
10037      <row>
10038       <entry>
10039        <indexterm>
10040         <primary>standard deviation</primary>
10041         <secondary>population</secondary>
10042        </indexterm>
10043        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
10044       </entry>
10045       <entry>
10046        <type>smallint</type>, <type>int</type>,
10047        <type>bigint</type>, <type>real</type>, <type>double
10048        precision</type>, or <type>numeric</type>
10049       </entry>
10050       <entry>
10051        <type>double precision</type> for floating-point arguments,
10052        otherwise <type>numeric</type>
10053       </entry>
10054       <entry>population standard deviation of the input values</entry>
10055      </row>
10056
10057      <row>
10058       <entry>
10059        <indexterm>
10060         <primary>standard deviation</primary>
10061         <secondary>sample</secondary>
10062        </indexterm>
10063        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
10064       </entry>
10065       <entry>
10066        <type>smallint</type>, <type>int</type>,
10067        <type>bigint</type>, <type>real</type>, <type>double
10068        precision</type>, or <type>numeric</type>
10069       </entry>
10070       <entry>
10071        <type>double precision</type> for floating-point arguments,
10072        otherwise <type>numeric</type>
10073       </entry>
10074       <entry>sample standard deviation of the input values</entry>
10075      </row>
10076
10077      <row>
10078       <entry>
10079        <indexterm>
10080         <primary>variance</primary>
10081        </indexterm>
10082        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
10083       </entry>
10084       <entry>
10085        <type>smallint</type>, <type>int</type>,
10086        <type>bigint</type>, <type>real</type>, <type>double
10087        precision</type>, or <type>numeric</type>
10088       </entry>
10089       <entry>
10090        <type>double precision</type> for floating-point arguments,
10091        otherwise <type>numeric</type>
10092       </entry>
10093       <entry>historical alias for <function>var_samp</function></entry>
10094      </row>
10095
10096      <row>
10097       <entry>
10098        <indexterm>
10099         <primary>variance</primary>
10100         <secondary>population</secondary>
10101        </indexterm>
10102        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
10103       </entry>
10104       <entry>
10105        <type>smallint</type>, <type>int</type>,
10106        <type>bigint</type>, <type>real</type>, <type>double
10107        precision</type>, or <type>numeric</type>
10108       </entry>
10109       <entry>
10110        <type>double precision</type> for floating-point arguments,
10111        otherwise <type>numeric</type>
10112       </entry>
10113       <entry>population variance of the input values (square of the population standard deviation)</entry>
10114      </row>
10115
10116      <row>
10117       <entry>
10118        <indexterm>
10119         <primary>variance</primary>
10120         <secondary>sample</secondary>
10121        </indexterm>
10122        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
10123       </entry>
10124       <entry>
10125        <type>smallint</type>, <type>int</type>,
10126        <type>bigint</type>, <type>real</type>, <type>double
10127        precision</type>, or <type>numeric</type>
10128       </entry>
10129       <entry>
10130        <type>double precision</type> for floating-point arguments,
10131        otherwise <type>numeric</type>
10132       </entry>
10133       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
10134      </row>
10135     </tbody>
10136    </tgroup>
10137   </table>
10138
10139  </sect1>
10140
10141
10142  <sect1 id="functions-subquery">
10143   <title>Subquery Expressions</title>
10144
10145   <indexterm>
10146    <primary>EXISTS</primary>
10147   </indexterm>
10148
10149   <indexterm>
10150    <primary>IN</primary>
10151   </indexterm>
10152
10153   <indexterm>
10154    <primary>NOT IN</primary>
10155   </indexterm>
10156
10157   <indexterm>
10158    <primary>ANY</primary>
10159   </indexterm>
10160
10161   <indexterm>
10162    <primary>ALL</primary>
10163   </indexterm>
10164
10165   <indexterm>
10166    <primary>SOME</primary>
10167   </indexterm>
10168
10169   <indexterm>
10170    <primary>subquery</primary>
10171   </indexterm>
10172
10173   <para>
10174    This section describes the <acronym>SQL</acronym>-compliant subquery
10175    expressions available in <productname>PostgreSQL</productname>.
10176    All of the expression forms documented in this section return
10177    Boolean (true/false) results.
10178   </para>
10179
10180   <sect2>
10181    <title><literal>EXISTS</literal></title>
10182
10183 <synopsis>
10184 EXISTS (<replaceable>subquery</replaceable>)
10185 </synopsis>
10186
10187   <para>
10188    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
10189    or <firstterm>subquery</firstterm>.  The
10190    subquery is evaluated to determine whether it returns any rows.
10191    If it returns at least one row, the result of <token>EXISTS</token> is
10192    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token> 
10193    is <quote>false</>.
10194   </para>
10195
10196   <para>
10197    The subquery can refer to variables from the surrounding query,
10198    which will act as constants during any one evaluation of the subquery.
10199   </para>
10200
10201   <para>
10202    The subquery will generally only be executed far enough to determine
10203    whether at least one row is returned, not all the way to completion.
10204    It is unwise to write a subquery that has any side effects (such as
10205    calling sequence functions); whether the side effects occur or not
10206    might be difficult to predict.
10207   </para>
10208
10209   <para>
10210    Since the result depends only on whether any rows are returned,
10211    and not on the contents of those rows, the output list of the
10212    subquery is normally uninteresting.  A common coding convention is
10213    to write all <literal>EXISTS</> tests in the form
10214    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
10215    this rule however, such as subqueries that use <token>INTERSECT</token>.
10216   </para>
10217
10218   <para>
10219    This simple example is like an inner join on <literal>col2</>, but
10220    it produces at most one output row for each <literal>tab1</> row,
10221    even if there are multiple matching <literal>tab2</> rows:
10222 <screen>
10223 SELECT col1 FROM tab1
10224     WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
10225 </screen>
10226   </para>
10227   </sect2>
10228
10229   <sect2>
10230    <title><literal>IN</literal></title>
10231
10232 <synopsis>
10233 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
10234 </synopsis>
10235
10236   <para>
10237    The right-hand side is a parenthesized
10238    subquery, which must return exactly one column.  The left-hand expression
10239    is evaluated and compared to each row of the subquery result.
10240    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10241    The result is <quote>false</> if no equal row is found (including the special
10242    case where the subquery returns no rows).
10243   </para>
10244
10245   <para>
10246    Note that if the left-hand expression yields null, or if there are
10247    no equal right-hand values and at least one right-hand row yields
10248    null, the result of the <token>IN</token> construct will be null, not false.
10249    This is in accordance with SQL's normal rules for Boolean combinations
10250    of null values.
10251   </para>
10252
10253   <para>
10254    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10255    be evaluated completely.
10256   </para>
10257
10258 <synopsis>
10259 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
10260 </synopsis>
10261
10262   <para>
10263    The left-hand side of this form of <token>IN</token> is a row constructor,
10264    as described in <xref linkend="sql-syntax-row-constructors">.
10265    The right-hand side is a parenthesized
10266    subquery, which must return exactly as many columns as there are
10267    expressions in the left-hand row.  The left-hand expressions are
10268    evaluated and compared row-wise to each row of the subquery result.
10269    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10270    The result is <quote>false</> if no equal row is found (including the special
10271    case where the subquery returns no rows).
10272   </para>
10273
10274   <para>
10275    As usual, null values in the rows are combined per
10276    the normal rules of SQL Boolean expressions.  Two rows are considered
10277    equal if all their corresponding members are non-null and equal; the rows
10278    are unequal if any corresponding members are non-null and unequal;
10279    otherwise the result of that row comparison is unknown (null).
10280    If all the per-row results are either unequal or null, with at least one
10281    null, then the result of <token>IN</token> is null.
10282   </para>
10283   </sect2>
10284
10285   <sect2>
10286    <title><literal>NOT IN</literal></title>
10287
10288 <synopsis>
10289 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10290 </synopsis>
10291
10292   <para>
10293    The right-hand side is a parenthesized
10294    subquery, which must return exactly one column.  The left-hand expression
10295    is evaluated and compared to each row of the subquery result.
10296    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10297    are found (including the special case where the subquery returns no rows).
10298    The result is <quote>false</> if any equal row is found.
10299   </para>
10300
10301   <para>
10302    Note that if the left-hand expression yields null, or if there are
10303    no equal right-hand values and at least one right-hand row yields
10304    null, the result of the <token>NOT IN</token> construct will be null, not true.
10305    This is in accordance with SQL's normal rules for Boolean combinations
10306    of null values.
10307   </para>
10308
10309   <para>
10310    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10311    be evaluated completely.
10312   </para>
10313
10314 <synopsis>
10315 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10316 </synopsis>
10317
10318   <para>
10319    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
10320    as described in <xref linkend="sql-syntax-row-constructors">.
10321    The right-hand side is a parenthesized
10322    subquery, which must return exactly as many columns as there are
10323    expressions in the left-hand row.  The left-hand expressions are
10324    evaluated and compared row-wise to each row of the subquery result.
10325    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10326    are found (including the special case where the subquery returns no rows).
10327    The result is <quote>false</> if any equal row is found.
10328   </para>
10329
10330   <para>
10331    As usual, null values in the rows are combined per
10332    the normal rules of SQL Boolean expressions.  Two rows are considered
10333    equal if all their corresponding members are non-null and equal; the rows
10334    are unequal if any corresponding members are non-null and unequal;
10335    otherwise the result of that row comparison is unknown (null).
10336    If all the per-row results are either unequal or null, with at least one
10337    null, then the result of <token>NOT IN</token> is null.
10338   </para>
10339   </sect2>
10340
10341   <sect2>
10342    <title><literal>ANY</literal>/<literal>SOME</literal></title>
10343
10344 <synopsis>
10345 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
10346 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
10347 </synopsis>
10348
10349   <para>
10350    The right-hand side is a parenthesized
10351    subquery, which must return exactly one column.  The left-hand expression
10352    is evaluated and compared to each row of the subquery result using the
10353    given <replaceable>operator</replaceable>, which must yield a Boolean
10354    result.
10355    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10356    The result is <quote>false</> if no true result is found (including the special
10357    case where the subquery returns no rows).
10358   </para>
10359
10360   <para>
10361    <token>SOME</token> is a synonym for <token>ANY</token>.
10362    <token>IN</token> is equivalent to <literal>= ANY</literal>.
10363   </para>
10364
10365   <para>
10366    Note that if there are no successes and at least one right-hand row yields
10367    null for the operator's result, the result of the <token>ANY</token> construct
10368    will be null, not false.
10369    This is in accordance with SQL's normal rules for Boolean combinations
10370    of null values.
10371   </para>
10372
10373   <para>
10374    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10375    be evaluated completely.
10376   </para>
10377
10378 <synopsis>
10379 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
10380 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
10381 </synopsis>
10382
10383   <para>
10384    The left-hand side of this form of <token>ANY</token> is a row constructor,
10385    as described in <xref linkend="sql-syntax-row-constructors">.
10386    The right-hand side is a parenthesized
10387    subquery, which must return exactly as many columns as there are
10388    expressions in the left-hand row.  The left-hand expressions are
10389    evaluated and compared row-wise to each row of the subquery result,
10390    using the given <replaceable>operator</replaceable>.
10391    The result of <token>ANY</token> is <quote>true</> if the comparison
10392    returns true for any subquery row.
10393    The result is <quote>false</> if the comparison returns false for every
10394    subquery row (including the special case where the subquery returns no
10395    rows).
10396    The result is NULL if the comparison does not return true for any row,
10397    and it returns NULL for at least one row.
10398   </para>
10399
10400   <para>
10401    See <xref linkend="row-wise-comparison"> for details about the meaning
10402    of a row-wise comparison.
10403   </para>
10404   </sect2>
10405
10406   <sect2>
10407    <title><literal>ALL</literal></title>
10408
10409 <synopsis>
10410 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10411 </synopsis>
10412
10413   <para>
10414    The right-hand side is a parenthesized
10415    subquery, which must return exactly one column.  The left-hand expression
10416    is evaluated and compared to each row of the subquery result using the
10417    given <replaceable>operator</replaceable>, which must yield a Boolean
10418    result.
10419    The result of <token>ALL</token> is <quote>true</> if all rows yield true
10420    (including the special case where the subquery returns no rows).
10421    The result is <quote>false</> if any false result is found.
10422    The result is NULL if the comparison does not return false for any row,
10423    and it returns NULL for at least one row.
10424   </para>
10425
10426   <para>
10427    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
10428   </para>
10429
10430   <para>
10431    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10432    be evaluated completely.
10433   </para>
10434
10435 <synopsis>
10436 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10437 </synopsis>
10438
10439   <para>
10440    The left-hand side of this form of <token>ALL</token> is a row constructor,
10441    as described in <xref linkend="sql-syntax-row-constructors">.
10442    The right-hand side is a parenthesized
10443    subquery, which must return exactly as many columns as there are
10444    expressions in the left-hand row.  The left-hand expressions are
10445    evaluated and compared row-wise to each row of the subquery result,
10446    using the given <replaceable>operator</replaceable>.
10447    The result of <token>ALL</token> is <quote>true</> if the comparison
10448    returns true for all subquery rows (including the special
10449    case where the subquery returns no rows).
10450    The result is <quote>false</> if the comparison returns false for any
10451    subquery row.
10452    The result is NULL if the comparison does not return false for any
10453    subquery row, and it returns NULL for at least one row.
10454   </para>
10455
10456   <para>
10457    See <xref linkend="row-wise-comparison"> for details about the meaning
10458    of a row-wise comparison.
10459   </para>
10460   </sect2>
10461
10462   <sect2>
10463    <title>Row-wise Comparison</title>
10464
10465    <indexterm zone="functions-subquery">
10466     <primary>comparison</primary>
10467     <secondary>subquery result row</secondary>
10468    </indexterm>
10469
10470 <synopsis>
10471 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
10472 </synopsis>
10473
10474   <para>
10475    The left-hand side is a row constructor,
10476    as described in <xref linkend="sql-syntax-row-constructors">.
10477    The right-hand side is a parenthesized subquery, which must return exactly
10478    as many columns as there are expressions in the left-hand row. Furthermore,
10479    the subquery cannot return more than one row.  (If it returns zero rows,
10480    the result is taken to be null.)  The left-hand side is evaluated and
10481    compared row-wise to the single subquery result row.
10482   </para>
10483
10484   <para>
10485    See <xref linkend="row-wise-comparison"> for details about the meaning
10486    of a row-wise comparison.
10487   </para>
10488   </sect2>
10489  </sect1>
10490
10491
10492  <sect1 id="functions-comparisons">
10493   <title>Row and Array Comparisons</title>
10494
10495   <indexterm>
10496    <primary>IN</primary>
10497   </indexterm>
10498
10499   <indexterm>
10500    <primary>NOT IN</primary>
10501   </indexterm>
10502
10503   <indexterm>
10504    <primary>ANY</primary>
10505   </indexterm>
10506
10507   <indexterm>
10508    <primary>ALL</primary>
10509   </indexterm>
10510
10511   <indexterm>
10512    <primary>SOME</primary>
10513   </indexterm>
10514
10515   <indexterm>
10516    <primary>row-wise comparison</primary>
10517   </indexterm>
10518
10519   <indexterm>
10520    <primary>comparison</primary>
10521    <secondary>row-wise</secondary>
10522   </indexterm>
10523
10524   <indexterm>
10525    <primary>IS DISTINCT FROM</primary>
10526   </indexterm>
10527
10528   <indexterm>
10529    <primary>IS NOT DISTINCT FROM</primary>
10530   </indexterm>
10531
10532   <para>
10533    This section describes several specialized constructs for making
10534    multiple comparisons between groups of values.  These forms are
10535    syntactically related to the subquery forms of the previous section,
10536    but do not involve subqueries.
10537    The forms involving array subexpressions are
10538    <productname>PostgreSQL</productname> extensions; the rest are
10539    <acronym>SQL</acronym>-compliant.
10540    All of the expression forms documented in this section return
10541    Boolean (true/false) results.
10542   </para>
10543
10544   <sect2>
10545    <title><literal>IN</literal></title>
10546
10547 <synopsis>
10548 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10549 </synopsis>
10550
10551   <para>
10552    The right-hand side is a parenthesized list
10553    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
10554    result is equal to any of the right-hand expressions.  This is a shorthand
10555    notation for
10556
10557 <synopsis>
10558 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
10559 OR
10560 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
10561 OR
10562 ...
10563 </synopsis>
10564   </para>
10565
10566   <para>
10567    Note that if the left-hand expression yields null, or if there are
10568    no equal right-hand values and at least one right-hand expression yields
10569    null, the result of the <token>IN</token> construct will be null, not false.
10570    This is in accordance with SQL's normal rules for Boolean combinations
10571    of null values.
10572   </para>
10573   </sect2>
10574
10575   <sect2>
10576    <title><literal>NOT IN</literal></title>
10577
10578 <synopsis>
10579 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10580 </synopsis>
10581
10582   <para>
10583    The right-hand side is a parenthesized list
10584    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
10585    result is unequal to all of the right-hand expressions.  This is a shorthand
10586    notation for
10587
10588 <synopsis>
10589 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
10590 AND
10591 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
10592 AND
10593 ...
10594 </synopsis>
10595   </para>
10596
10597   <para>
10598    Note that if the left-hand expression yields null, or if there are
10599    no equal right-hand values and at least one right-hand expression yields
10600    null, the result of the <token>NOT IN</token> construct will be null, not true
10601    as one might naively expect.
10602    This is in accordance with SQL's normal rules for Boolean combinations
10603    of null values.
10604   </para>
10605
10606   <tip>
10607   <para>
10608    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
10609    cases.  However, null values are much more likely to trip up the novice when
10610    working with <token>NOT IN</token> than when working with <token>IN</token>.
10611    It's best to express your condition positively if possible.
10612   </para>
10613   </tip>
10614   </sect2>
10615
10616   <sect2>
10617    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
10618
10619 <synopsis>
10620 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
10621 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
10622 </synopsis>
10623
10624   <para>
10625    The right-hand side is a parenthesized expression, which must yield an
10626    array value.
10627    The left-hand expression
10628    is evaluated and compared to each element of the array using the
10629    given <replaceable>operator</replaceable>, which must yield a Boolean
10630    result.
10631    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10632    The result is <quote>false</> if no true result is found (including the special
10633    case where the array has zero elements).
10634   </para>
10635
10636   <para>
10637    If the array expression yields a null array, the result of
10638    <token>ANY</token> will be null.  If the left-hand expression yields null,
10639    the result of <token>ANY</token> is ordinarily null (though a non-strict
10640    comparison operator could possibly yield a different result).
10641    Also, if the right-hand array contains any null elements and no true
10642    comparison result is obtained, the result of <token>ANY</token>
10643    will be null, not false (again, assuming a strict comparison operator).
10644    This is in accordance with SQL's normal rules for Boolean combinations
10645    of null values.
10646   </para>
10647
10648   <para>
10649    <token>SOME</token> is a synonym for <token>ANY</token>.
10650   </para>
10651   </sect2>
10652
10653   <sect2>
10654    <title><literal>ALL</literal> (array)</title>
10655
10656 <synopsis>
10657 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
10658 </synopsis>
10659
10660   <para>
10661    The right-hand side is a parenthesized expression, which must yield an
10662    array value.
10663    The left-hand expression
10664    is evaluated and compared to each element of the array using the
10665    given <replaceable>operator</replaceable>, which must yield a Boolean
10666    result.
10667    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
10668    (including the special case where the array has zero elements).
10669    The result is <quote>false</> if any false result is found.
10670   </para>
10671
10672   <para>
10673    If the array expression yields a null array, the result of
10674    <token>ALL</token> will be null.  If the left-hand expression yields null,
10675    the result of <token>ALL</token> is ordinarily null (though a non-strict
10676    comparison operator could possibly yield a different result).
10677    Also, if the right-hand array contains any null elements and no false
10678    comparison result is obtained, the result of <token>ALL</token>
10679    will be null, not true (again, assuming a strict comparison operator).
10680    This is in accordance with SQL's normal rules for Boolean combinations
10681    of null values.
10682   </para>
10683   </sect2>
10684
10685   <sect2 id="row-wise-comparison">
10686    <title>Row-wise Comparison</title>
10687
10688 <synopsis>
10689 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
10690 </synopsis>
10691
10692   <para>
10693    Each side is a row constructor,
10694    as described in <xref linkend="sql-syntax-row-constructors">.
10695    The two row values must have the same number of fields.
10696    Each side is evaluated and they are compared row-wise.  Row comparisons
10697    are allowed when the <replaceable>operator</replaceable> is
10698    <literal>=</>,
10699    <literal>&lt;&gt;</>,
10700    <literal>&lt;</>,
10701    <literal>&lt;=</>,
10702    <literal>&gt;</> or
10703    <literal>&gt;=</>,
10704    or has semantics similar to one of these.  (To be specific, an operator
10705    can be a row comparison operator if it is a member of a B-Tree operator
10706    class, or is the negator of the <literal>=</> member of a B-Tree operator
10707    class.)
10708   </para>
10709
10710   <para>
10711    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
10712    from the others.  Two rows are considered
10713    equal if all their corresponding members are non-null and equal; the rows
10714    are unequal if any corresponding members are non-null and unequal;
10715    otherwise the result of the row comparison is unknown (null).
10716   </para>
10717
10718   <para>
10719    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
10720    <literal>&gt;=</> cases, the row elements are compared left-to-right,
10721    stopping as soon as an unequal or null pair of elements is found.
10722    If either of this pair of elements is null, the result of the
10723    row comparison is unknown (null); otherwise comparison of this pair
10724    of elements determines the result.  For example,
10725    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
10726    yields true, not null, because the third pair of elements are not
10727    considered.
10728   </para>
10729
10730   <note>
10731    <para>
10732     Prior to <productname>PostgreSQL</productname> 8.2, the
10733     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
10734     cases were not handled per SQL specification.  A comparison like
10735     <literal>ROW(a,b) &lt; ROW(c,d)</>
10736     was implemented as
10737     <literal>a &lt; c AND b &lt; d</>
10738     whereas the correct behavior is equivalent to
10739     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
10740    </para>
10741   </note>
10742
10743 <synopsis>
10744 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
10745 </synopsis>
10746
10747   <para>
10748    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
10749    but it does not yield null for null inputs.  Instead, any null value is
10750    considered unequal to (distinct from) any non-null value, and any two
10751    nulls are considered equal (not distinct).  Thus the result will always
10752    be either true or false, never null.
10753   </para>
10754
10755 <synopsis>
10756 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
10757 </synopsis>
10758
10759   <para>
10760    This construct is similar to a <literal>=</literal> row comparison,
10761    but it does not yield null for null inputs.  Instead, any null value is
10762    considered unequal to (distinct from) any non-null value, and any two
10763    nulls are considered equal (not distinct).  Thus the result will always
10764    be either true or false, never null.
10765   </para>
10766
10767   <note>
10768    <para>
10769     The SQL specification requires row-wise comparison to return NULL if the
10770     result depends on comparing two NULL values or a NULL and a non-NULL.
10771     <productname>PostgreSQL</productname> does this only when comparing the
10772     results of two row constructors or comparing a row constructor to the
10773     output of a subquery (as in <xref linkend="functions-subquery">).
10774     In other contexts where two composite-type values are compared, two
10775     NULL field values are considered equal, and a NULL is considered larger
10776     than a non-NULL.  This is necessary in order to have consistent sorting
10777     and indexing behavior for composite types.
10778    </para>
10779   </note>
10780
10781   </sect2>
10782  </sect1>
10783
10784  <sect1 id="functions-srf">
10785   <title>Set Returning Functions</title>
10786
10787   <indexterm zone="functions-srf">
10788    <primary>set returning functions</primary>
10789    <secondary>functions</secondary>
10790   </indexterm>
10791
10792   <indexterm>
10793    <primary>generate_series</primary>
10794   </indexterm>
10795
10796   <para>
10797    This section describes functions that possibly return more than one row.
10798    Currently the only functions in this class are series generating functions,
10799    as detailed in <xref linkend="functions-srf-series"> and
10800    <xref linkend="functions-srf-subscripts">.
10801   </para>
10802
10803   <table id="functions-srf-series">
10804    <title>Series Generating Functions</title>
10805    <tgroup cols="4">
10806     <thead>
10807      <row>
10808       <entry>Function</entry>
10809       <entry>Argument Type</entry>
10810       <entry>Return Type</entry>
10811       <entry>Description</entry>
10812      </row>
10813     </thead>
10814
10815     <tbody>
10816      <row>
10817       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>)</literal></entry>
10818       <entry><type>int</type> or <type>bigint</type></entry>
10819       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
10820       <entry>
10821        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
10822        with a step size of one
10823       </entry>
10824      </row>
10825
10826      <row>
10827       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</literal></entry>
10828       <entry><type>int</type> or <type>bigint</type></entry>
10829       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
10830       <entry>
10831        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
10832        with a step size of <parameter>step</parameter>
10833       </entry>
10834      </row>
10835
10836      <row>
10837       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</literal></entry>
10838       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
10839       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
10840       <entry>
10841        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
10842        with a step size of <parameter>step</parameter>
10843       </entry>
10844      </row>
10845
10846     </tbody>
10847    </tgroup>
10848   </table>
10849
10850   <para>
10851    When <parameter>step</parameter> is positive, zero rows are returned if
10852    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
10853    Conversely, when <parameter>step</parameter> is negative, zero rows are
10854    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
10855    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
10856    for <parameter>step</parameter> to be zero. Some examples follow:
10857 <programlisting>
10858 select * from generate_series(2,4);
10859  generate_series
10860 -----------------
10861                2
10862                3
10863                4
10864 (3 rows)
10865
10866 select * from generate_series(5,1,-2);
10867  generate_series
10868 -----------------
10869                5
10870                3
10871                1
10872 (3 rows)
10873
10874 select * from generate_series(4,3);
10875  generate_series
10876 -----------------
10877 (0 rows)
10878
10879 -- this example relies on the date-plus-integer operator
10880 select current_date + s.a as dates from generate_series(0,14,7) as s(a);
10881    dates
10882 ------------
10883  2004-02-05
10884  2004-02-12
10885  2004-02-19
10886 (3 rows)
10887
10888 select * from generate_series('2008-03-01 00:00'::timestamp,
10889                               '2008-03-04 12:00', '10 hours');
10890    generate_series   
10891 ---------------------
10892  2008-03-01 00:00:00
10893  2008-03-01 10:00:00
10894  2008-03-01 20:00:00
10895  2008-03-02 06:00:00
10896  2008-03-02 16:00:00
10897  2008-03-03 02:00:00
10898  2008-03-03 12:00:00
10899  2008-03-03 22:00:00
10900  2008-03-04 08:00:00
10901 (9 rows)
10902 </programlisting>
10903   </para>
10904
10905   <table id="functions-srf-subscripts">
10906    <title>Subscript Generating Functions</title>
10907    <tgroup cols="3">
10908     <thead>
10909      <row>
10910       <entry>Function</entry>
10911       <entry>Return Type</entry>
10912       <entry>Description</entry>
10913      </row>
10914     </thead>
10915
10916     <tbody>
10917      <row>
10918       <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</literal></entry>
10919       <entry><type>setof int</type></entry>
10920       <entry>
10921        Generate a series comprising the given array's subscripts.
10922       </entry>
10923      </row>
10924
10925      <row>
10926       <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</literal></entry>
10927       <entry><type>setof int</type></entry>
10928       <entry>
10929        Generate a series comprising the given array's subscripts. When
10930        <parameter>reverse</parameter> is true, the series is returned in
10931        reverse order.
10932       </entry>
10933      </row>
10934
10935     </tbody>
10936    </tgroup>
10937   </table>
10938
10939   <indexterm>
10940    <primary>generate_subscripts</primary>
10941   </indexterm>
10942
10943   <para>
10944    <function>generate_subscripts</> is a convenience function that generates
10945    the set of valid subscripts for the specified dimension of the given
10946    array.
10947    Zero rows are returned for arrays that do not have the requested dimension,
10948    or for NULL arrays (but valid subscripts are returned for NULL array
10949    elements).  Some examples follow:
10950 <programlisting>
10951 -- basic usage
10952 select generate_subscripts('{NULL,1,NULL,2}'::int[], 1) as s;
10953  s 
10954 ---
10955  1
10956  2
10957  3
10958  4
10959 (4 rows)
10960
10961 -- presenting an array, the subscript and the subscripted
10962 -- value requires a subquery
10963 select * from arrays;
10964          a          
10965 --------------------
10966  {-1,-2}
10967  {100,200}
10968 (2 rows)
10969
10970 select a as array, s as subscript, a[s] as value
10971 from (select generate_subscripts(a, 1) as s, a from arrays) foo;
10972    array   | subscript | value 
10973 -----------+-----------+-------
10974  {-1,-2}   |         1 |    -1
10975  {-1,-2}   |         2 |    -2
10976  {100,200} |         1 |   100
10977  {100,200} |         2 |   200
10978 (4 rows)
10979
10980 -- unnest a 2D array
10981 create or replace function unnest2(anyarray)
10982 returns setof anyelement as $$
10983 select $1[i][j] 
10984    from generate_subscripts($1,1) g1(i),
10985         generate_subscripts($1,2) g2(j);
10986 $$ language sql immutable;
10987 CREATE FUNCTION
10988 postgres=# select * from unnest2(array[[1,2],[3,4]]);
10989  unnest2 
10990 ---------
10991        1
10992        2
10993        3
10994        4
10995 (4 rows)
10996 </programlisting>
10997   </para>
10998
10999  </sect1>
11000
11001  <sect1 id="functions-info">
11002   <title>System Information Functions</title>
11003
11004   <para>
11005    <xref linkend="functions-info-session-table"> shows several
11006    functions that extract session and system information.
11007   </para>
11008
11009   <para>
11010    In addition to the functions listed in this section, there are a number of
11011    functions related to the statistics system that also provide system
11012    information. See <xref linkend="monitoring-stats-views"> for more
11013    information.
11014   </para>
11015
11016    <table id="functions-info-session-table">
11017     <title>Session Information Functions</title>
11018     <tgroup cols="3">
11019      <thead>
11020       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11021      </thead>
11022
11023      <tbody>
11024       <row>
11025        <entry><literal><function>current_catalog</function></literal></entry>
11026        <entry><type>name</type></entry>
11027        <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
11028       </row>
11029
11030       <row>
11031        <entry><literal><function>current_database</function>()</literal></entry>
11032        <entry><type>name</type></entry>
11033        <entry>name of current database</entry>
11034       </row>
11035
11036       <row>
11037        <entry><literal><function>current_schema</function>[()]</literal></entry>
11038        <entry><type>name</type></entry>
11039        <entry>name of current schema</entry>
11040       </row>
11041
11042       <row>
11043        <entry><literal><function>current_schemas</function>(<type>boolean</type>)</literal></entry>
11044        <entry><type>name[]</type></entry>
11045        <entry>names of schemas in search path optionally including implicit schemas</entry>
11046       </row>
11047
11048       <row>
11049        <entry><literal><function>current_user</function></literal></entry>
11050        <entry><type>name</type></entry>
11051        <entry>user name of current execution context</entry>
11052       </row>
11053
11054       <row>
11055        <entry><literal><function>current_query</function></literal></entry>
11056        <entry><type>text</type></entry>
11057        <entry>text of the currently executing query (might contain more than one statement)</entry>
11058       </row>  
11059
11060       <row>
11061        <!-- See also the entry for this in monitoring.sgml -->
11062        <entry><literal><function>pg_backend_pid</function>()</literal></entry>
11063        <entry><type>int</type></entry>
11064        <entry>
11065         Process ID of the server process attached to the current session
11066        </entry>
11067       </row>
11068
11069       <row>
11070        <entry><literal><function>inet_client_addr</function>()</literal></entry>
11071        <entry><type>inet</type></entry>
11072        <entry>address of the remote connection</entry>
11073       </row>
11074
11075       <row>
11076        <entry><literal><function>inet_client_port</function>()</literal></entry>
11077        <entry><type>int</type></entry>
11078        <entry>port of the remote connection</entry>
11079       </row>
11080
11081       <row>
11082        <entry><literal><function>inet_server_addr</function>()</literal></entry>
11083        <entry><type>inet</type></entry>
11084        <entry>address of the local connection</entry>
11085       </row>
11086
11087       <row>
11088        <entry><literal><function>inet_server_port</function>()</literal></entry>
11089        <entry><type>int</type></entry>
11090        <entry>port of the local connection</entry>
11091       </row>
11092
11093       <row>
11094        <entry><literal><function>pg_my_temp_schema</function>()</literal></entry>
11095        <entry><type>oid</type></entry>
11096        <entry>OID of session's temporary schema, or 0 if none</entry>
11097       </row>
11098
11099       <row>
11100        <entry><literal><function>pg_is_other_temp_schema</function>(<type>oid</type>)</literal></entry>
11101        <entry><type>boolean</type></entry>
11102        <entry>is schema another session's temporary schema?</entry>
11103       </row>
11104
11105       <row>
11106        <entry><literal><function>pg_postmaster_start_time</function>()</literal></entry>
11107        <entry><type>timestamp with time zone</type></entry>
11108        <entry>server start time</entry>
11109       </row>
11110
11111       <row>
11112        <entry><literal><function>pg_conf_load_time</function>()</literal></entry>
11113        <entry><type>timestamp with time zone</type></entry>
11114        <entry>configuration load time</entry>
11115       </row>
11116
11117       <row>
11118        <entry><literal><function>session_user</function></literal></entry>
11119        <entry><type>name</type></entry>
11120        <entry>session user name</entry>
11121       </row>
11122
11123       <row>
11124        <entry><literal><function>user</function></literal></entry>
11125        <entry><type>name</type></entry>
11126        <entry>equivalent to <function>current_user</function></entry>
11127       </row>
11128
11129       <row>
11130        <entry><literal><function>version</function>()</literal></entry>
11131        <entry><type>text</type></entry>
11132        <entry><productname>PostgreSQL</> version information</entry>
11133       </row>
11134      </tbody>
11135     </tgroup>
11136    </table>
11137
11138    <indexterm>
11139     <primary>user</primary>
11140     <secondary>current</secondary>
11141    </indexterm>
11142
11143    <indexterm>
11144     <primary>schema</primary>
11145     <secondary>current</secondary>
11146    </indexterm>
11147
11148    <indexterm>
11149     <primary>search path</primary>
11150     <secondary>current</secondary>
11151    </indexterm>
11152
11153    <indexterm>
11154     <primary>current_catalog</primary>
11155    </indexterm>
11156
11157    <indexterm>
11158     <primary>current_database</primary>
11159    </indexterm>
11160
11161    <indexterm>
11162     <primary>current_schema</primary>
11163    </indexterm>
11164
11165    <indexterm>
11166     <primary>current_user</primary>
11167    </indexterm>
11168
11169    <para>
11170     The <function>session_user</function> is normally the user who initiated
11171     the current database connection; but superusers can change this setting
11172     with <xref linkend="sql-set-session-authorization" endterm="sql-set-session-authorization-title">.
11173     The <function>current_user</function> is the user identifier
11174     that is applicable for permission checking. Normally, it is equal
11175     to the session user, but it can be changed with
11176     <xref linkend="sql-set-role" endterm="sql-set-role-title">.
11177     It also changes during the execution of
11178     functions with the attribute <literal>SECURITY DEFINER</literal>.
11179     In Unix parlance, the session user is the <quote>real user</quote> and
11180     the current user is the <quote>effective user</quote>.
11181    </para>
11182
11183    <note>
11184     <para>
11185      <function>current_catalog</function>, <function>current_schema</function>,
11186      <function>current_user</function>, <function>session_user</function>,
11187      and <function>user</function> have special syntactic status
11188      in <acronym>SQL</acronym>: they must be called without trailing
11189      parentheses (optional in PostgreSQL in the case
11190      of <function>current_schema</function>).
11191     </para>
11192    </note>
11193
11194    <para>
11195     <function>current_schema</function> returns the name of the schema that is
11196     at the front of the search path (or a null value if the search path is
11197     empty).  This is the schema that will be used for any tables or
11198     other named objects that are created without specifying a target schema.
11199     <function>current_schemas(boolean)</function> returns an array of the names of all
11200     schemas presently in the search path.  The Boolean option determines whether or not
11201     implicitly included system schemas such as <literal>pg_catalog</> are included in the search 
11202     path returned.
11203    </para>
11204
11205    <note>
11206     <para>
11207      The search path can be altered at run time.  The command is:
11208 <programlisting>
11209 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
11210 </programlisting>
11211     </para>
11212    </note>
11213
11214    <indexterm>
11215     <primary>inet_client_addr</primary>
11216    </indexterm>
11217
11218    <indexterm>
11219     <primary>inet_client_port</primary>
11220    </indexterm>
11221
11222    <indexterm>
11223     <primary>inet_server_addr</primary>
11224    </indexterm>
11225
11226    <indexterm>
11227     <primary>inet_server_port</primary>
11228    </indexterm>
11229
11230    <para>
11231      <function>inet_client_addr</function> returns the IP address of the
11232      current client, and <function>inet_client_port</function> returns the
11233      port number.
11234      <function>inet_server_addr</function> returns the IP address on which
11235      the server accepted the current connection, and
11236      <function>inet_server_port</function> returns the port number.
11237      All these functions return NULL if the current connection is via a
11238      Unix-domain socket.
11239    </para>
11240
11241    <indexterm>
11242     <primary>pg_my_temp_schema</primary>
11243    </indexterm>
11244
11245    <indexterm>
11246     <primary>pg_is_other_temp_schema</primary>
11247    </indexterm>
11248
11249    <para>
11250     <function>pg_my_temp_schema</function> returns the OID of the current
11251     session's temporary schema, or 0 if it has none (because it has not
11252     created any temporary tables).
11253     <function>pg_is_other_temp_schema</function> returns true if the
11254     given OID is the OID of any other session's temporary schema.
11255     (This can be useful, for example, to exclude other sessions' temporary
11256     tables from a catalog display.)
11257    </para>
11258
11259    <indexterm>
11260     <primary>pg_postmaster_start_time</primary>
11261    </indexterm>
11262
11263    <para>
11264     <function>pg_postmaster_start_time</function> returns the
11265     <type>timestamp with time zone</type> when the
11266     server started.
11267    </para>
11268
11269    <indexterm>
11270     <primary>pg_conf_load_time</primary>
11271    </indexterm>
11272
11273    <para>
11274     <function>pg_conf_load_time</function> returns the
11275     <type>timestamp with time zone</type> when the
11276     server configuration files were last loaded.
11277     (If the current session was alive at the time, this will be the time
11278     when the session itself re-read the configuration files, so the
11279     reading will vary a little in different sessions.  Otherwise it is
11280     the time when the postmaster process re-read the configuration files.)
11281    </para>
11282
11283    <indexterm>
11284     <primary>version</primary>
11285    </indexterm>
11286
11287    <para>
11288     <function>version</function> returns a string describing the
11289     <productname>PostgreSQL</productname> server's version.
11290    </para>
11291
11292   <indexterm>
11293    <primary>privilege</primary>
11294    <secondary>querying</secondary>
11295   </indexterm>
11296
11297   <para>
11298    <xref linkend="functions-info-access-table"> lists functions that
11299    allow the user to query object access privileges programmatically.
11300    See <xref linkend="ddl-priv"> for more information about
11301    privileges.
11302   </para>
11303
11304    <table id="functions-info-access-table">
11305     <title>Access Privilege Inquiry Functions</title>
11306     <tgroup cols="3">
11307      <thead>
11308       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11309      </thead>
11310
11311      <tbody>
11312       <row>
11313        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
11314                                   <parameter>database</parameter>,
11315                                   <parameter>privilege</parameter>)</literal>
11316        </entry>
11317        <entry><type>boolean</type></entry>
11318        <entry>does user have privilege for database</entry>
11319       </row>
11320       <row>
11321        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
11322                                   <parameter>privilege</parameter>)</literal>
11323        </entry>
11324        <entry><type>boolean</type></entry>
11325        <entry>does current user have privilege for database</entry>
11326       </row>
11327       <row>
11328        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
11329                                   <parameter>function</parameter>,
11330                                   <parameter>privilege</parameter>)</literal>
11331        </entry>
11332        <entry><type>boolean</type></entry>
11333        <entry>does user have privilege for function</entry>
11334       </row>
11335       <row>
11336        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
11337                                   <parameter>privilege</parameter>)</literal>
11338        </entry>
11339        <entry><type>boolean</type></entry>
11340        <entry>does current user have privilege for function</entry>
11341       </row>
11342       <row>
11343        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
11344                                   <parameter>language</parameter>,
11345                                   <parameter>privilege</parameter>)</literal>
11346        </entry>
11347        <entry><type>boolean</type></entry>
11348        <entry>does user have privilege for language</entry>
11349       </row>
11350       <row>
11351        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
11352                                   <parameter>privilege</parameter>)</literal>
11353        </entry>
11354        <entry><type>boolean</type></entry>
11355        <entry>does current user have privilege for language</entry>
11356       </row>
11357       <row>
11358        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
11359                                   <parameter>schema</parameter>,
11360                                   <parameter>privilege</parameter>)</literal>
11361        </entry>
11362        <entry><type>boolean</type></entry>
11363        <entry>does user have privilege for schema</entry>
11364       </row>
11365       <row>
11366        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
11367                                   <parameter>privilege</parameter>)</literal>
11368        </entry>
11369        <entry><type>boolean</type></entry>
11370        <entry>does current user have privilege for schema</entry>
11371       </row>
11372       <row>
11373        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
11374                                   <parameter>table</parameter>,
11375                                   <parameter>privilege</parameter>)</literal>
11376        </entry>
11377        <entry><type>boolean</type></entry>
11378        <entry>does user have privilege for table</entry>
11379       </row>
11380       <row>
11381        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
11382                                   <parameter>privilege</parameter>)</literal>
11383        </entry>
11384        <entry><type>boolean</type></entry>
11385        <entry>does current user have privilege for table</entry>
11386       </row>
11387       <row>
11388        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
11389                                   <parameter>tablespace</parameter>,
11390                                   <parameter>privilege</parameter>)</literal>
11391        </entry>
11392        <entry><type>boolean</type></entry>
11393        <entry>does user have privilege for tablespace</entry>
11394       </row>
11395       <row>
11396        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
11397                                   <parameter>privilege</parameter>)</literal>
11398        </entry>
11399        <entry><type>boolean</type></entry>
11400        <entry>does current user have privilege for tablespace</entry>
11401       </row>
11402       <row>
11403        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
11404                                   <parameter>role</parameter>,
11405                                   <parameter>privilege</parameter>)</literal>
11406        </entry>
11407        <entry><type>boolean</type></entry>
11408        <entry>does user have privilege for role</entry>
11409       </row>
11410       <row>
11411        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
11412                                   <parameter>privilege</parameter>)</literal>
11413        </entry>
11414        <entry><type>boolean</type></entry>
11415        <entry>does current user have privilege for role</entry>
11416       </row>
11417      </tbody>
11418     </tgroup>
11419    </table>
11420
11421    <indexterm>
11422     <primary>has_database_privilege</primary>
11423    </indexterm>
11424    <indexterm>
11425     <primary>has_function_privilege</primary>
11426    </indexterm>
11427    <indexterm>
11428     <primary>has_language_privilege</primary>
11429    </indexterm>
11430    <indexterm>
11431     <primary>has_schema_privilege</primary>
11432    </indexterm>
11433    <indexterm>
11434     <primary>has_table_privilege</primary>
11435    </indexterm>
11436    <indexterm>
11437     <primary>has_tablespace_privilege</primary>
11438    </indexterm>
11439    <indexterm>
11440     <primary>pg_has_role</primary>
11441    </indexterm>
11442
11443    <para>
11444     <function>has_database_privilege</function> checks whether a user
11445     can access a database in a particular way.  The possibilities for its
11446     arguments are analogous to <function>has_table_privilege</function>.
11447     The desired access privilege type must evaluate to
11448     <literal>CREATE</literal>,
11449     <literal>CONNECT</literal>,
11450     <literal>TEMPORARY</literal>, or
11451     <literal>TEMP</literal> (which is equivalent to
11452     <literal>TEMPORARY</literal>).
11453    </para>
11454
11455    <para>
11456     <function>has_function_privilege</function> checks whether a user
11457     can access a function in a particular way.  The possibilities for its
11458     arguments are analogous to <function>has_table_privilege</function>.
11459     When specifying a function by a text string rather than by OID,
11460     the allowed input is the same as for the <type>regprocedure</> data type
11461     (see <xref linkend="datatype-oid">).
11462     The desired access privilege type must evaluate to
11463     <literal>EXECUTE</literal>.
11464     An example is:
11465 <programlisting>
11466 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
11467 </programlisting>
11468    </para>
11469
11470    <para>
11471     <function>has_language_privilege</function> checks whether a user
11472     can access a procedural language in a particular way.  The possibilities
11473     for its arguments are analogous to <function>has_table_privilege</function>.
11474     The desired access privilege type must evaluate to
11475     <literal>USAGE</literal>.
11476    </para>
11477
11478    <para>
11479     <function>has_schema_privilege</function> checks whether a user
11480     can access a schema in a particular way.  The possibilities for its
11481     arguments are analogous to <function>has_table_privilege</function>.
11482     The desired access privilege type must evaluate to
11483     <literal>CREATE</literal> or
11484     <literal>USAGE</literal>.
11485    </para>
11486
11487    <para>
11488     <function>has_table_privilege</function> checks whether a user
11489     can access a table in a particular way.  The user can be
11490     specified by name or by OID
11491     (<literal>pg_authid.oid</literal>), or if the argument is
11492     omitted
11493     <function>current_user</function> is assumed.  The table can be specified
11494     by name or by OID.  (Thus, there are actually six variants of
11495     <function>has_table_privilege</function>, which can be distinguished by
11496     the number and types of their arguments.)  When specifying by name,
11497     the name can be schema-qualified if necessary.
11498     The desired access privilege type
11499     is specified by a text string, which must evaluate to one of the
11500     values <literal>SELECT</literal>, <literal>INSERT</literal>,
11501     <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
11502     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.
11503     (Case of the string is not significant, however.)
11504     An example is:
11505 <programlisting>
11506 SELECT has_table_privilege('myschema.mytable', 'select');
11507 </programlisting>
11508    </para>
11509
11510    <para>
11511     <function>has_tablespace_privilege</function> checks whether a user
11512     can access a tablespace in a particular way.  The possibilities for its
11513     arguments are analogous to <function>has_table_privilege</function>.
11514     The desired access privilege type must evaluate to
11515     <literal>CREATE</literal>.
11516    </para>
11517
11518    <para>
11519     <function>pg_has_role</function> checks whether a user
11520     can access a role in a particular way.  The possibilities for its
11521     arguments are analogous to <function>has_table_privilege</function>.
11522     The desired access privilege type must evaluate to
11523     <literal>MEMBER</literal> or
11524     <literal>USAGE</literal>.
11525     <literal>MEMBER</literal> denotes direct or indirect membership in
11526     the role (that is, the right to do <command>SET ROLE</>), while
11527     <literal>USAGE</literal> denotes whether the privileges of the role
11528     are immediately available without doing <command>SET ROLE</>.
11529    </para>
11530
11531   <para>
11532    To test whether a user holds a grant option on the privilege,
11533    append <literal>WITH GRANT OPTION</literal> to the privilege key
11534    word; for example <literal>'UPDATE WITH GRANT OPTION'</literal>.
11535   </para>
11536
11537   <para>
11538    <xref linkend="functions-info-schema-table"> shows functions that
11539    determine whether a certain object is <firstterm>visible</> in the
11540    current schema search path.
11541    For example, a table is said to be visible if its
11542    containing schema is in the search path and no table of the same
11543    name appears earlier in the search path.  This is equivalent to the
11544    statement that the table can be referenced by name without explicit
11545    schema qualification.  To list the names of all visible tables:
11546 <programlisting>
11547 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
11548 </programlisting>
11549   </para>
11550
11551    <table id="functions-info-schema-table">
11552     <title>Schema Visibility Inquiry Functions</title>
11553     <tgroup cols="3">
11554      <thead>
11555       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11556      </thead>
11557
11558      <tbody>
11559       <row>
11560        <entry><literal><function>pg_conversion_is_visible</function>(<parameter>conversion_oid</parameter>)</literal>
11561        </entry>
11562        <entry><type>boolean</type></entry>
11563        <entry>is conversion visible in search path</entry>
11564       </row>
11565       <row>
11566        <entry><literal><function>pg_function_is_visible</function>(<parameter>function_oid</parameter>)</literal>
11567        </entry>
11568        <entry><type>boolean</type></entry>
11569        <entry>is function visible in search path</entry>
11570       </row>
11571       <row>
11572        <entry><literal><function>pg_operator_is_visible</function>(<parameter>operator_oid</parameter>)</literal>
11573        </entry>
11574        <entry><type>boolean</type></entry>
11575        <entry>is operator visible in search path</entry>
11576       </row>
11577       <row>
11578        <entry><literal><function>pg_opclass_is_visible</function>(<parameter>opclass_oid</parameter>)</literal>
11579        </entry>
11580        <entry><type>boolean</type></entry>
11581        <entry>is operator class visible in search path</entry>
11582       </row>
11583       <row>
11584        <entry><literal><function>pg_table_is_visible</function>(<parameter>table_oid</parameter>)</literal>
11585        </entry>
11586        <entry><type>boolean</type></entry>
11587        <entry>is table visible in search path</entry>
11588       </row>
11589       <row>
11590        <entry><literal><function>pg_ts_config_is_visible</function>(<parameter>config_oid</parameter>)</literal>
11591        </entry>
11592        <entry><type>boolean</type></entry>
11593        <entry>is text search configuration visible in search path</entry>
11594       </row>
11595       <row>
11596        <entry><literal><function>pg_ts_dict_is_visible</function>(<parameter>dict_oid</parameter>)</literal>
11597        </entry>
11598        <entry><type>boolean</type></entry>
11599        <entry>is text search dictionary visible in search path</entry>
11600       </row>
11601       <row>
11602        <entry><literal><function>pg_ts_parser_is_visible</function>(<parameter>parser_oid</parameter>)</literal>
11603        </entry>
11604        <entry><type>boolean</type></entry>
11605        <entry>is text search parser visible in search path</entry>
11606       </row>
11607       <row>
11608        <entry><literal><function>pg_ts_template_is_visible</function>(<parameter>template_oid</parameter>)</literal>
11609        </entry>
11610        <entry><type>boolean</type></entry>
11611        <entry>is text search template visible in search path</entry>
11612       </row>
11613       <row>
11614        <entry><literal><function>pg_type_is_visible</function>(<parameter>type_oid</parameter>)</literal>
11615        </entry>
11616        <entry><type>boolean</type></entry>
11617        <entry>is type (or domain) visible in search path</entry>
11618       </row>
11619      </tbody>
11620     </tgroup>
11621    </table>
11622
11623    <indexterm>
11624     <primary>pg_conversion_is_visible</primary>
11625    </indexterm>
11626    <indexterm>
11627     <primary>pg_function_is_visible</primary>
11628    </indexterm>
11629    <indexterm>
11630     <primary>pg_operator_is_visible</primary>
11631    </indexterm>
11632    <indexterm>
11633     <primary>pg_opclass_is_visible</primary>
11634    </indexterm>
11635    <indexterm>
11636     <primary>pg_table_is_visible</primary>
11637    </indexterm>
11638    <indexterm>
11639     <primary>pg_ts_config_is_visible</primary>
11640    </indexterm>
11641    <indexterm>
11642     <primary>pg_ts_dict_is_visible</primary>
11643    </indexterm>
11644    <indexterm>
11645     <primary>pg_ts_parser_is_visible</primary>
11646    </indexterm>
11647    <indexterm>
11648     <primary>pg_ts_template_is_visible</primary>
11649    </indexterm>
11650    <indexterm>
11651     <primary>pg_type_is_visible</primary>
11652    </indexterm>
11653
11654    <para>
11655     Each function performs the visibility check for one type of database
11656     object.  Note that <function>pg_table_is_visible</function> can also be used
11657     with views, indexes and sequences; <function>pg_type_is_visible</function>
11658     can also be used with domains. For functions and operators, an object in
11659     the search path is visible if there is no object of the same name
11660     <emphasis>and argument data type(s)</> earlier in the path.  For operator
11661     classes, both name and associated index access method are considered.
11662    </para>
11663
11664    <para>
11665     All these functions require object OIDs to identify the object to be
11666     checked.  If you want to test an object by name, it is convenient to use
11667     the OID alias types (<type>regclass</>, <type>regtype</>,
11668     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
11669     or <type>regdictionary</>),
11670     for example:
11671 <programlisting>
11672 SELECT pg_type_is_visible('myschema.widget'::regtype);
11673 </programlisting>
11674     Note that it would not make much sense to test an unqualified name in
11675     this way &mdash; if the name can be recognized at all, it must be visible.
11676    </para>
11677
11678    <indexterm>
11679     <primary>format_type</primary>
11680    </indexterm>
11681
11682    <indexterm>
11683     <primary>pg_get_keywords</primary>
11684    </indexterm>
11685
11686    <indexterm>
11687     <primary>pg_get_viewdef</primary>
11688    </indexterm>
11689
11690    <indexterm>
11691     <primary>pg_get_ruledef</primary>
11692    </indexterm>
11693
11694    <indexterm>
11695     <primary>pg_get_functiondef</primary>
11696    </indexterm>
11697
11698    <indexterm>
11699     <primary>pg_get_function_arguments</primary>
11700    </indexterm>
11701
11702    <indexterm>
11703     <primary>pg_get_function_result</primary>
11704    </indexterm>
11705
11706    <indexterm>
11707     <primary>pg_get_indexdef</primary>
11708    </indexterm>
11709
11710    <indexterm>
11711     <primary>pg_get_triggerdef</primary>
11712    </indexterm>
11713
11714    <indexterm>
11715     <primary>pg_get_constraintdef</primary>
11716    </indexterm>
11717
11718    <indexterm>
11719     <primary>pg_get_expr</primary>
11720    </indexterm>
11721
11722    <indexterm>
11723     <primary>pg_get_userbyid</primary>
11724    </indexterm>
11725
11726    <indexterm>
11727     <primary>pg_get_serial_sequence</primary>
11728    </indexterm>
11729
11730    <indexterm>
11731     <primary>pg_tablespace_databases</primary>
11732    </indexterm>
11733
11734    <indexterm>
11735     <primary>pg_typeof</primary>
11736    </indexterm>
11737
11738   <para>
11739    <xref linkend="functions-info-catalog-table"> lists functions that
11740    extract information from the system catalogs.
11741   </para>
11742
11743    <table id="functions-info-catalog-table">
11744     <title>System Catalog Information Functions</title>
11745     <tgroup cols="3">
11746      <thead>
11747       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11748      </thead>
11749
11750      <tbody>
11751       <row>
11752        <entry><literal><function>format_type</function>(<parameter>type_oid</parameter>, <parameter>typemod</>)</literal></entry>
11753        <entry><type>text</type></entry>
11754        <entry>get SQL name of a data type</entry>
11755       </row>
11756       <row>
11757        <entry><literal><function>pg_get_keywords</function>()</literal></entry>
11758        <entry><type>setof record</type></entry>
11759        <entry>get list of SQL keywords and their categories</entry>
11760       </row>
11761       <row>
11762        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>)</literal></entry>
11763        <entry><type>text</type></entry>
11764        <entry>get definition of a constraint</entry>
11765       </row>
11766       <row>
11767        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11768        <entry><type>text</type></entry>
11769        <entry>get definition of a constraint</entry>
11770       </row>
11771       <row>
11772        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>)</literal></entry>
11773        <entry><type>text</type></entry>
11774        <entry>decompile internal form of an expression, assuming that any Vars
11775        in it refer to the relation indicated by the second parameter</entry>
11776       </row>
11777       <row>
11778        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</literal></entry>
11779        <entry><type>text</type></entry>
11780        <entry>decompile internal form of an expression, assuming that any Vars
11781        in it refer to the relation indicated by the second parameter</entry>
11782       </row>
11783       <row>
11784        <entry><literal><function>pg_get_functiondef</function>(<parameter>func_oid</parameter>)</literal></entry>
11785        <entry><type>text</type></entry>
11786        <entry>get definition of a function</entry>
11787       </row>
11788       <row>
11789        <entry><literal><function>pg_get_function_arguments</function>(<parameter>func_oid</parameter>)</literal></entry>
11790        <entry><type>text</type></entry>
11791        <entry>get argument list for function</entry>
11792       </row>
11793       <row>
11794        <entry><literal><function>pg_get_function_result</function>(<parameter>func_oid</parameter>)</literal></entry>
11795        <entry><type>text</type></entry>
11796        <entry>get <literal>RETURNS</> clause for function</entry>
11797       </row>
11798       <row>
11799        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
11800        <entry><type>text</type></entry>
11801        <entry>get <command>CREATE INDEX</> command for index</entry>
11802       </row>
11803       <row>
11804        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</literal></entry>
11805        <entry><type>text</type></entry>
11806        <entry>get <command>CREATE INDEX</> command for index,
11807        or definition of just one index column when
11808        <parameter>column_no</> is not zero</entry>
11809       </row>
11810       <row>
11811        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>)</literal></entry>
11812        <entry><type>text</type></entry>
11813        <entry>get <command>CREATE RULE</> command for rule</entry>
11814       </row>
11815       <row>
11816        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11817        <entry><type>text</type></entry>
11818        <entry>get <command>CREATE RULE</> command for rule</entry>
11819       </row>
11820       <row>
11821        <entry><literal><function>pg_get_serial_sequence</function>(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</literal></entry>
11822        <entry><type>text</type></entry>
11823        <entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
11824        uses</entry>
11825       </row>
11826       <row>
11827        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
11828        <entry><type>text</type></entry>
11829        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
11830       </row>
11831       <row>
11832        <entry><literal><function>pg_get_userbyid</function>(<parameter>roleid</parameter>)</literal></entry>
11833        <entry><type>name</type></entry>
11834        <entry>get role name with given ID</entry>
11835       </row>
11836       <row>
11837        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>)</literal></entry>
11838        <entry><type>text</type></entry>
11839        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
11840       </row>
11841       <row>
11842        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</literal></entry>
11843        <entry><type>text</type></entry>
11844        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
11845       </row>
11846       <row>
11847        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>)</literal></entry>
11848        <entry><type>text</type></entry>
11849        <entry>get underlying <command>SELECT</command> command for view</entry>
11850       </row>
11851       <row>
11852        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11853        <entry><type>text</type></entry>
11854        <entry>get underlying <command>SELECT</command> command for view</entry>
11855       </row>
11856       <row>
11857        <entry><literal><function>pg_tablespace_databases</function>(<parameter>tablespace_oid</parameter>)</literal></entry>
11858        <entry><type>setof oid</type></entry>
11859        <entry>get the set of database OIDs that have objects in the tablespace</entry>
11860       </row>
11861       <row>
11862        <entry><literal><function>pg_typeof</function>(<parameter>any</parameter>)</literal></entry>
11863        <entry><type>regtype</type></entry>
11864        <entry>get the data type of any value</entry>
11865       </row>
11866      </tbody>
11867     </tgroup>
11868    </table>
11869
11870   <para>
11871    <function>format_type</function> returns the SQL name of a data type that
11872    is identified by its type OID and possibly a type modifier.  Pass NULL
11873    for the type modifier if no specific modifier is known.
11874   </para>
11875
11876   <para>
11877    <function>pg_get_keywords</function> returns a set of records describing
11878    the SQL keywords recognized by the server. The <structfield>word</> column
11879    contains the keyword.  The <structfield>catcode</> column contains a
11880    category code: <literal>U</> for unreserved, <literal>C</> for column name,
11881    <literal>T</> for type or function name, or <literal>R</> for reserved.
11882    The <structfield>catdesc</> column contains a possibly-localized string
11883    describing the category.
11884   </para>
11885
11886   <para>
11887    <function>pg_get_constraintdef</function>,
11888    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
11889    and <function>pg_get_triggerdef</function>, respectively reconstruct the
11890    creating command for a constraint, index, rule, or trigger. (Note that this
11891    is a decompiled reconstruction, not the original text of the command.)
11892    <function>pg_get_expr</function> decompiles the internal form of an
11893    individual expression, such as the default value for a column.  It can be
11894    useful when examining the contents of system catalogs.
11895    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
11896    query that defines a view. Most of these functions come in two variants,
11897    one of which can optionally <quote>pretty-print</> the result.  The
11898    pretty-printed format is more readable, but the default format is more
11899    likely to be interpreted the same way by future versions of
11900    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
11901    purposes.  Passing <literal>false</> for the pretty-print parameter yields
11902    the same result as the variant that does not have the parameter at all.
11903   </para>
11904
11905   <para>
11906    <function>pg_get_functiondef</> returns a complete
11907    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
11908    <function>pg_get_function_arguments</function> returns the argument list
11909    of a function, in the form it would need to appear in within
11910    <command>CREATE FUNCTION</>.
11911    <function>pg_get_function_result</function> similarly returns the
11912    appropriate <literal>RETURNS</> clause for the function.
11913   </para>
11914
11915   <para>
11916    <function>pg_get_serial_sequence</function> returns the name of the
11917    sequence associated with a column, or NULL if no sequence is associated
11918    with the column.  The first input parameter is a table name with
11919    optional schema, and the second parameter is a column name.  Because
11920    the first parameter is potentially a schema and table, it is not treated
11921    as a double-quoted identifier, meaning it is lowercased by default,
11922    while the second parameter, being just a column name, is treated as
11923    double-quoted and has its case preserved.  The function returns a value
11924    suitably formatted for passing to the sequence functions (see <xref
11925    linkend="functions-sequence">).  This association can be modified or
11926    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
11927    probably should have been called
11928    <function>pg_get_owned_sequence</function>; its name reflects the fact
11929    that it's typically used with <type>serial</> or <type>bigserial</>
11930    columns.)
11931   </para>
11932
11933   <para>
11934    <function>pg_get_userbyid</function> extracts a role's name given
11935    its OID.
11936   </para>
11937
11938   <para>
11939    <function>pg_tablespace_databases</function> allows a tablespace to be
11940    examined. It returns the set of OIDs of databases that have objects stored
11941    in the tablespace. If this function returns any rows, the tablespace is not
11942    empty and cannot be dropped. To display the specific objects populating the
11943    tablespace, you will need to connect to the databases identified by
11944    <function>pg_tablespace_databases</function> and query their
11945    <structname>pg_class</> catalogs.
11946   </para>
11947
11948   <para>
11949    <function>pg_typeof</function> returns the OID of the data type of the
11950    value that is passed to it.  This can be helpful for troubleshooting or
11951    dynamically constructing SQL queries.  The function is declared as
11952    returning <type>regtype</>, which is an OID alias type (see
11953    <xref linkend="datatype-oid">); this means that it is the same as an
11954    OID for comparison purposes but displays as a type name.  For example:
11955 <programlisting>
11956 SELECT pg_typeof(33);
11957
11958  pg_typeof 
11959 -----------
11960  integer
11961 (1 row)
11962
11963 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
11964  typlen 
11965 --------
11966       4
11967 (1 row)
11968 </programlisting>
11969   </para>
11970
11971    <indexterm>
11972     <primary>col_description</primary>
11973    </indexterm>
11974
11975    <indexterm>
11976     <primary>obj_description</primary>
11977    </indexterm>
11978
11979    <indexterm>
11980     <primary>shobj_description</primary>
11981    </indexterm>
11982
11983    <indexterm>
11984     <primary>comment</primary>
11985     <secondary sortas="database objects">about database objects</secondary>
11986    </indexterm>
11987
11988    <para>
11989     The functions shown in <xref linkend="functions-info-comment-table">
11990     extract comments previously stored with the <xref linkend="sql-comment"
11991     endterm="sql-comment-title"> command.  A null value is returned if no
11992     comment could be found matching the specified parameters.
11993    </para>
11994
11995    <table id="functions-info-comment-table">
11996     <title>Comment Information Functions</title>
11997     <tgroup cols="3">
11998      <thead>
11999       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12000      </thead>
12001
12002      <tbody>
12003       <row>
12004        <entry><literal><function>col_description</function>(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</literal></entry>
12005        <entry><type>text</type></entry>
12006        <entry>get comment for a table column</entry>
12007       </row>
12008       <row>
12009        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12010        <entry><type>text</type></entry>
12011        <entry>get comment for a database object</entry>
12012       </row>
12013       <row>
12014        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>)</literal></entry>
12015        <entry><type>text</type></entry>
12016        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
12017       </row>
12018       <row>
12019        <entry><literal><function>shobj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12020        <entry><type>text</type></entry>
12021        <entry>get comment for a shared database object</entry>
12022       </row>
12023      </tbody>
12024     </tgroup>
12025    </table>
12026
12027    <para>
12028     <function>col_description</function> returns the comment for a table column,
12029     which is specified by the OID of its table and its column number.
12030     <function>obj_description</function> cannot be used for table columns since
12031     columns do not have OIDs of their own.
12032    </para>
12033
12034    <para>
12035     The two-parameter form of <function>obj_description</function> returns the
12036     comment for a database object specified by its OID and the name of the
12037     containing system catalog.  For example,
12038     <literal>obj_description(123456,'pg_class')</literal>
12039     would retrieve the comment for a table with OID 123456.
12040     The one-parameter form of <function>obj_description</function> requires only
12041     the object OID.  It is now deprecated since there is no guarantee that
12042     OIDs are unique across different system catalogs; therefore, the wrong
12043     comment could be returned.
12044    </para>
12045
12046    <para>
12047     <function>shobj_description</function> is used just like
12048     <function>obj_description</function> only that it is used for retrieving
12049     comments on shared objects.  Some system catalogs are global to all
12050     databases within each cluster and their descriptions are stored globally
12051     as well.
12052    </para>
12053
12054    <indexterm>
12055     <primary>txid_current</primary>
12056    </indexterm>
12057
12058    <indexterm>
12059     <primary>txid_current_snapshot</primary>
12060    </indexterm>
12061
12062    <indexterm>
12063     <primary>txid_snapshot_xmin</primary>
12064    </indexterm>
12065
12066    <indexterm>
12067     <primary>txid_snapshot_xmax</primary>
12068    </indexterm>
12069
12070    <indexterm>
12071     <primary>txid_snapshot_xip</primary>
12072    </indexterm>
12073
12074    <indexterm>
12075     <primary>txid_visible_in_snapshot</primary>
12076    </indexterm>
12077
12078    <para>
12079     The functions shown in <xref linkend="functions-txid-snapshot">
12080     export server internal transaction information to user level.  The main
12081     use of these functions is to determine which transactions were committed
12082     between two snapshots.
12083    </para>
12084
12085    <table id="functions-txid-snapshot">
12086     <title>Transaction IDs and snapshots</title>
12087     <tgroup cols="3">
12088      <thead>
12089       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12090      </thead>
12091
12092      <tbody>
12093       <row>
12094        <entry><literal><function>txid_current</function>()</literal></entry>
12095        <entry><type>bigint</type></entry>
12096        <entry>get current transaction ID</entry>
12097       </row>
12098       <row>
12099        <entry><literal><function>txid_current_snapshot</function>()</literal></entry>
12100        <entry><type>txid_snapshot</type></entry>
12101        <entry>get current snapshot</entry>
12102       </row>
12103       <row>
12104        <entry><literal><function>txid_snapshot_xmin</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12105        <entry><type>bigint</type></entry>
12106        <entry>get xmin of snapshot</entry>
12107       </row>
12108       <row>
12109        <entry><literal><function>txid_snapshot_xmax</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12110        <entry><type>bigint</type></entry>
12111        <entry>get xmax of snapshot</entry>
12112       </row>
12113       <row>
12114        <entry><literal><function>txid_snapshot_xip</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12115        <entry><type>setof bigint</type></entry>
12116        <entry>get in-progress transaction IDs in snapshot</entry>
12117       </row>
12118       <row>
12119        <entry><literal><function>txid_visible_in_snapshot</function>(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</literal></entry>
12120        <entry><type>boolean</type></entry>
12121        <entry>is transaction ID visible in snapshot?</entry>
12122       </row>
12123      </tbody>
12124     </tgroup>
12125    </table>
12126
12127    <para>
12128     The internal transaction ID type (<type>xid</>) is 32 bits wide and so
12129     it wraps around every 4 billion transactions.  However, these functions
12130     export a 64-bit format that is extended with an <quote>epoch</> counter
12131     so that it will not wrap around for the life of an installation.
12132     The data type used by these functions, <type>txid_snapshot</type>,
12133     stores information about transaction ID
12134     visibility at a particular moment in time.  Its components are
12135     described in <xref linkend="functions-txid-snapshot-parts">.
12136    </para>
12137
12138    <table id="functions-txid-snapshot-parts">
12139     <title>Snapshot components</title>
12140     <tgroup cols="2">
12141      <thead>
12142       <row>
12143        <entry>Name</entry>
12144        <entry>Description</entry>
12145       </row>
12146      </thead>
12147
12148      <tbody>
12149
12150       <row>
12151        <entry><type>xmin</type></entry>
12152        <entry>
12153          Earliest transaction ID (txid) that is still active.  All earlier
12154          transactions will either be committed and visible, or rolled
12155          back and dead.
12156        </entry>
12157       </row>
12158
12159       <row>
12160        <entry><type>xmax</type></entry>
12161        <entry>
12162         First as-yet-unassigned txid.  All txids later than this one are
12163         not yet started as of the time of the snapshot, and thus invisible.
12164        </entry>
12165       </row>
12166
12167       <row>
12168        <entry><type>xip_list</type></entry>
12169        <entry>
12170         Active txids at the time of the snapshot.  The list
12171         includes only those active txids between <literal>xmin</>
12172         and <literal>xmax</>; there might be active txids higher
12173         than xmax.  A txid that is <literal>xmin &lt;= txid &lt;
12174         xmax</literal> and not in this list was already completed
12175         at the time of the snapshot, and thus either visible or
12176         dead according to its commit status.  The list does not
12177         include txids of subtransactions.
12178        </entry>
12179       </row>
12180
12181      </tbody>
12182     </tgroup>
12183    </table>
12184
12185    <para>
12186     <type>txid_snapshot</>'s textual representation is
12187     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
12188     For example <literal>10:20:10,14,15</literal> means
12189     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
12190    </para>
12191   </sect1>
12192
12193   <sect1 id="functions-admin">
12194    <title>System Administration Functions</title>
12195
12196    <para>
12197     <xref linkend="functions-admin-set-table"> shows the functions
12198     available to query and alter run-time configuration parameters.
12199    </para>
12200
12201    <table id="functions-admin-set-table">
12202     <title>Configuration Settings Functions</title>
12203     <tgroup cols="3">
12204      <thead>
12205       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12206      </thead>
12207
12208      <tbody>
12209       <row>
12210        <entry>
12211         <literal><function>current_setting</function>(<parameter>setting_name</parameter>)</literal>
12212        </entry>
12213        <entry><type>text</type></entry>
12214        <entry>current value of setting</entry>
12215       </row>
12216       <row>
12217        <entry>
12218         <literal><function>set_config(<parameter>setting_name</parameter>,
12219                              <parameter>new_value</parameter>,
12220                              <parameter>is_local</parameter>)</function></literal>
12221        </entry>
12222        <entry><type>text</type></entry>
12223        <entry>set parameter and return new value</entry>
12224       </row>
12225      </tbody>
12226     </tgroup>
12227    </table>
12228
12229    <indexterm>
12230     <primary>SET</primary>
12231    </indexterm>
12232
12233    <indexterm>
12234     <primary>SHOW</primary>
12235    </indexterm>
12236
12237    <indexterm>
12238     <primary>configuration</primary>
12239     <secondary sortas="server">of the server</secondary>
12240     <tertiary>functions</tertiary>
12241    </indexterm>
12242
12243    <para>
12244     The function <function>current_setting</function> yields the
12245     current value of the setting <parameter>setting_name</parameter>.
12246     It corresponds to the <acronym>SQL</acronym> command
12247     <command>SHOW</command>.  An example:
12248 <programlisting>
12249 SELECT current_setting('datestyle');
12250
12251  current_setting
12252 -----------------
12253  ISO, MDY
12254 (1 row)
12255 </programlisting>
12256    </para>
12257
12258    <para>
12259     <function>set_config</function> sets the parameter
12260     <parameter>setting_name</parameter> to
12261     <parameter>new_value</parameter>.  If
12262     <parameter>is_local</parameter> is <literal>true</literal>, the
12263     new value will only apply to the current transaction. If you want
12264     the new value to apply for the current session, use
12265     <literal>false</literal> instead. The function corresponds to the
12266     SQL command <command>SET</command>. An example:
12267 <programlisting>
12268 SELECT set_config('log_statement_stats', 'off', false);
12269
12270  set_config
12271 ------------
12272  off
12273 (1 row)
12274 </programlisting>
12275    </para>
12276
12277    <indexterm>
12278     <primary>pg_cancel_backend</primary>
12279    </indexterm>
12280    <indexterm>
12281     <primary>pg_terminate_backend</primary>
12282    </indexterm>
12283    <indexterm>
12284     <primary>pg_reload_conf</primary>
12285    </indexterm>
12286    <indexterm>
12287     <primary>pg_rotate_logfile</primary>
12288    </indexterm>
12289
12290    <indexterm>
12291     <primary>signal</primary>
12292     <secondary sortas="backend">backend processes</secondary>
12293    </indexterm>
12294
12295    <para>
12296     The functions shown in <xref
12297     linkend="functions-admin-signal-table"> send control signals to
12298     other server processes.  Use of these functions is restricted
12299     to superusers.
12300    </para>
12301
12302    <table id="functions-admin-signal-table">
12303     <title>Server Signalling Functions</title>
12304     <tgroup cols="3">
12305      <thead>
12306       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12307       </row>
12308      </thead>
12309
12310      <tbody>
12311       <row>
12312        <entry>
12313         <literal><function>pg_cancel_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12314         </entry>
12315        <entry><type>boolean</type></entry>
12316        <entry>Cancel a backend's current query</entry>
12317       </row>
12318       <row>
12319        <entry>
12320         <literal><function>pg_terminate_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12321         </entry>
12322        <entry><type>boolean</type></entry>
12323        <entry>Terminate a backend</entry>
12324       </row>
12325       <row>
12326        <entry>
12327         <literal><function>pg_reload_conf</function>()</literal>
12328         </entry>
12329        <entry><type>boolean</type></entry>
12330        <entry>Cause server processes to reload their configuration files</entry>
12331       </row>
12332       <row>
12333        <entry>
12334         <literal><function>pg_rotate_logfile</function>()</literal>
12335         </entry>
12336        <entry><type>boolean</type></entry>
12337        <entry>Rotate server's log file</entry>
12338       </row>
12339      </tbody>
12340     </tgroup>
12341    </table>
12342
12343    <para>
12344     Each of these functions returns <literal>true</literal> if
12345     successful and <literal>false</literal> otherwise.
12346    </para>
12347
12348    <para>
12349     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
12350     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
12351     respectively) to backend processes identified by process ID.
12352     The process ID of an active backend can be found from
12353     the <structfield>procpid</structfield> column in the
12354     <structname>pg_stat_activity</structname> view, or by listing the
12355     <command>postgres</command> processes on the server with
12356     <application>ps</>.
12357    </para>
12358
12359    <para>
12360     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
12361     to the server, causing the configuration files
12362     to be reloaded by all server processes.
12363    </para>
12364
12365    <para>
12366     <function>pg_rotate_logfile</> signals the log-file manager to switch
12367     to a new output file immediately.  This works only when the built-in
12368     log collector is running, since otherwise there is no log-file manager 
12369     subprocess.
12370    </para>
12371
12372    <indexterm>
12373     <primary>pg_start_backup</primary>
12374    </indexterm>
12375    <indexterm>
12376     <primary>pg_stop_backup</primary>
12377    </indexterm>
12378    <indexterm>
12379     <primary>pg_switch_xlog</primary>
12380    </indexterm>
12381    <indexterm>
12382     <primary>pg_current_xlog_location</primary>
12383    </indexterm>
12384    <indexterm>
12385     <primary>pg_current_xlog_insert_location</primary>
12386    </indexterm>
12387    <indexterm>
12388     <primary>pg_xlogfile_name_offset</primary>
12389    </indexterm>
12390    <indexterm>
12391     <primary>pg_xlogfile_name</primary>
12392    </indexterm>
12393    <indexterm>
12394     <primary>backup</primary>
12395    </indexterm>
12396
12397    <para>
12398     The functions shown in <xref
12399     linkend="functions-admin-backup-table"> assist in making on-line backups.
12400     Use of the first three functions is restricted to superusers.
12401    </para>
12402
12403    <table id="functions-admin-backup-table">
12404     <title>Backup Control Functions</title>
12405     <tgroup cols="3">
12406      <thead>
12407       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12408       </row>
12409      </thead>
12410
12411      <tbody>
12412       <row>
12413        <entry>
12414         <literal><function>pg_start_backup</function>(<parameter>label</> <type>text</>)</literal>
12415         </entry>
12416        <entry><type>text</type></entry>
12417        <entry>Set up for performing on-line backup</entry>
12418       </row>
12419       <row>
12420        <entry>
12421         <literal><function>pg_stop_backup</function>()</literal>
12422         </entry>
12423        <entry><type>text</type></entry>
12424        <entry>Finish performing on-line backup</entry>
12425       </row>
12426       <row>
12427        <entry>
12428         <literal><function>pg_switch_xlog</function>()</literal>
12429         </entry>
12430        <entry><type>text</type></entry>
12431        <entry>Force switch to a new transaction log file</entry>
12432       </row>
12433       <row>
12434        <entry>
12435         <literal><function>pg_current_xlog_location</function>()</literal>
12436         </entry>
12437        <entry><type>text</type></entry>
12438        <entry>Get current transaction log write location</entry>
12439       </row>
12440       <row>
12441        <entry>
12442         <literal><function>pg_current_xlog_insert_location</function>()</literal>
12443         </entry>
12444        <entry><type>text</type></entry>
12445        <entry>Get current transaction log insert location</entry>
12446       </row>
12447       <row>
12448        <entry>
12449         <literal><function>pg_xlogfile_name_offset</function>(<parameter>location</> <type>text</>)</literal>
12450         </entry>
12451        <entry><type>text</>, <type>integer</></entry>
12452        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
12453       </row>
12454       <row>
12455        <entry>
12456         <literal><function>pg_xlogfile_name</function>(<parameter>location</> <type>text</>)</literal>
12457         </entry>
12458        <entry><type>text</type></entry>
12459        <entry>Convert transaction log location string to file name</entry>
12460       </row>
12461      </tbody>
12462     </tgroup>
12463    </table>
12464
12465    <para>
12466     <function>pg_start_backup</> accepts a single parameter which is an
12467     arbitrary user-defined label for the backup.  (Typically this would be
12468     the name under which the backup dump file will be stored.)  The function
12469     writes a backup label file into the database cluster's data directory,
12470     and then returns the backup's starting transaction log location as text.  The user
12471     need not pay any attention to this result value, but it is provided in
12472     case it is of use. 
12473 <programlisting>
12474 postgres=# select pg_start_backup('label_goes_here');
12475  pg_start_backup
12476 -----------------
12477  0/D4445B8
12478 (1 row)
12479 </programlisting>
12480    </para>
12481
12482    <para>
12483     <function>pg_stop_backup</> removes the label file created by
12484     <function>pg_start_backup</>, and instead creates a backup history file in
12485     the transaction log archive area.  The history file includes the label given to
12486     <function>pg_start_backup</>, the starting and ending transaction log locations for
12487     the backup, and the starting and ending times of the backup.  The return
12488     value is the backup's ending transaction log location (which again might be of little
12489     interest).  After noting the ending location, the current transaction log insertion
12490     point is automatically advanced to the next transaction log file, so that the
12491     ending transaction log file can be archived immediately to complete the backup.
12492    </para>
12493
12494    <para>
12495     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the 
12496     current file to be archived (assuming you are using continuous archiving).
12497     The result is the ending transaction log location within the just-completed transaction log file.
12498     If there has been no transaction log activity since the last transaction log switch,
12499     <function>pg_switch_xlog</> does nothing and returns the end location
12500     of the previous transaction log file.
12501    </para>
12502
12503    <para>
12504     <function>pg_current_xlog_location</> displays the current transaction log write
12505     location in the same format used by the above functions.  Similarly,
12506     <function>pg_current_xlog_insert_location</> displays the current transaction log
12507     insertion point.  The insertion point is the <quote>logical</> end
12508     of the transaction log
12509     at any instant, while the write location is the end of what has actually
12510     been written out from the server's internal buffers.  The write location
12511     is the end of what can be examined from outside the server, and is usually
12512     what you want if you are interested in archiving partially-complete transaction log
12513     files.  The insertion point is made available primarily for server
12514     debugging purposes.  These are both read-only operations and do not
12515     require superuser permissions.
12516    </para>
12517
12518    <para>
12519     You can use <function>pg_xlogfile_name_offset</> to extract the
12520     corresponding transaction log file name and byte offset from the results of any of the
12521     above functions.  For example:
12522 <programlisting>
12523 postgres=# select * from pg_xlogfile_name_offset(pg_stop_backup());
12524         file_name         | file_offset 
12525 --------------------------+-------------
12526  00000001000000000000000D |     4039624
12527 (1 row)
12528 </programlisting>
12529     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
12530     When the given transaction log location is exactly at a transaction log file boundary, both
12531     these functions return the name of the preceding transaction log file.
12532     This is usually the desired behavior for managing transaction log archiving
12533     behavior, since the preceding file is the last one that currently
12534     needs to be archived.
12535    </para>
12536
12537    <para>
12538     For details about proper usage of these functions, see
12539     <xref linkend="continuous-archiving">.
12540    </para>
12541
12542    <para>
12543     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
12544     the actual disk space usage of database objects.
12545    </para>
12546
12547    <indexterm>
12548     <primary>pg_column_size</primary>
12549    </indexterm>
12550    <indexterm>
12551     <primary>pg_database_size</primary>
12552    </indexterm>
12553    <indexterm>
12554     <primary>pg_relation_size</primary>
12555    </indexterm>
12556    <indexterm>
12557     <primary>pg_size_pretty</primary>
12558    </indexterm>
12559    <indexterm>
12560     <primary>pg_tablespace_size</primary>
12561    </indexterm>
12562    <indexterm>
12563     <primary>pg_total_relation_size</primary>
12564    </indexterm>
12565
12566    <table id="functions-admin-dbsize">
12567     <title>Database Object Size Functions</title>
12568     <tgroup cols="3">
12569      <thead>
12570       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12571       </row>
12572      </thead>
12573
12574      <tbody>
12575       <row>
12576        <entry><literal><function>pg_column_size</function>(<type>any</type>)</literal></entry>
12577        <entry><type>int</type></entry>
12578        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
12579       </row>
12580       <row>
12581        <entry>
12582         <literal><function>pg_database_size</function>(<type>oid</type>)</literal>
12583         </entry>
12584        <entry><type>bigint</type></entry>
12585        <entry>Disk space used by the database with the specified OID</entry>
12586       </row>
12587       <row>
12588        <entry>
12589         <literal><function>pg_database_size</function>(<type>name</type>)</literal>
12590         </entry>
12591        <entry><type>bigint</type></entry>
12592        <entry>Disk space used by the database with the specified name</entry>
12593       </row>
12594       <row>
12595        <entry>
12596         <literal><function>pg_relation_size</function>(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</literal>
12597         </entry>
12598        <entry><type>bigint</type></entry>
12599        <entry>
12600         Disk space used by the specified fork, <literal>'main'</literal> or
12601         <literal>'fsm'</literal>, of a table or index with the specified OID
12602         or name. The table name can be qualified with a schema name
12603        </entry>
12604       </row>
12605       <row>
12606        <entry>
12607         <literal><function>pg_relation_size</function>(<parameter>relation</parameter> <type>regclass</type>)</literal>
12608         </entry>
12609        <entry><type>bigint</type></entry>
12610        <entry>
12611         Shorthand for <literal>pg_relation_size(..., 'main')</literal>
12612        </entry>
12613       </row>
12614       <row>
12615        <entry>
12616         <literal><function>pg_size_pretty</function>(<type>bigint</type>)</literal>
12617         </entry>
12618        <entry><type>text</type></entry>
12619        <entry>Converts a size in bytes into a human-readable format with size units</entry>
12620       </row>
12621       <row>
12622        <entry>
12623         <literal><function>pg_tablespace_size</function>(<type>oid</type>)</literal>
12624         </entry>
12625        <entry><type>bigint</type></entry>
12626        <entry>Disk space used by the tablespace with the specified OID</entry>
12627       </row>
12628       <row>
12629        <entry>
12630         <literal><function>pg_tablespace_size</function>(<type>name</type>)</literal>
12631         </entry>
12632        <entry><type>bigint</type></entry>
12633        <entry>Disk space used by the tablespace with the specified name</entry>
12634       </row>
12635       <row>
12636        <entry>
12637         <literal><function>pg_total_relation_size</function>(<type>regclass</type>)</literal>
12638         </entry>
12639        <entry><type>bigint</type></entry>
12640        <entry>
12641         Total disk space used by the table with the specified OID or name,
12642         including indexes and toasted data.  The table name can be
12643         qualified with a schema name
12644        </entry>
12645       </row>
12646      </tbody>
12647     </tgroup>
12648    </table>
12649
12650    <para>
12651     <function>pg_column_size</> shows the space used to store any individual
12652     data value.
12653    </para>
12654
12655    <para>
12656     <function>pg_database_size</function> and <function>pg_tablespace_size</>
12657     accept the OID or name of a database or tablespace, and return the total
12658     disk space used therein.
12659    </para>
12660
12661    <para>
12662     <function>pg_relation_size</> accepts the OID or name of a table, index or
12663     toast table, and returns the size in bytes. Specifying
12664     <literal>'main'</literal> or leaving out the second argument returns the
12665     size of the main data fork of the relation. Specifying
12666     <literal>'fsm'</literal> returns the size of the
12667     Free Space Map (see <xref linkend="storage-fsm">) associated with the
12668     relation.
12669    </para>
12670
12671    <para>
12672     <function>pg_size_pretty</> can be used to format the result of one of
12673     the other functions in a human-readable way, using kB, MB, GB or TB as
12674     appropriate.
12675    </para>
12676
12677    <para>
12678     <function>pg_total_relation_size</> accepts the OID or name of a
12679     table or toast table, and returns the size in bytes of the data
12680     and all associated indexes and toast tables.
12681    </para>
12682
12683    <para>
12684     The functions shown in <xref
12685     linkend="functions-admin-genfile"> provide native file access to
12686     files on the machine hosting the server. Only files within the
12687     database cluster directory and the <varname>log_directory</> can be
12688     accessed.  Use a relative path for files within the cluster directory,
12689     and a path matching the <varname>log_directory</> configuration setting
12690     for log files.  Use of these functions is restricted to superusers.
12691    </para>
12692
12693    <table id="functions-admin-genfile">
12694     <title>Generic File Access Functions</title>
12695     <tgroup cols="3">
12696      <thead>
12697       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12698       </row>
12699      </thead>
12700
12701      <tbody>
12702       <row>
12703        <entry>
12704         <literal><function>pg_ls_dir</function>(<parameter>dirname</> <type>text</>)</literal>
12705        </entry>
12706        <entry><type>setof text</type></entry>
12707        <entry>List the contents of a directory</entry>
12708       </row>
12709       <row>
12710        <entry>
12711         <literal><function>pg_read_file</function>(<parameter>filename</> <type>text</>, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>)</literal>
12712        </entry>
12713        <entry><type>text</type></entry>
12714        <entry>Return the contents of a text file</entry>
12715       </row>
12716       <row>
12717        <entry>
12718         <literal><function>pg_stat_file</function>(<parameter>filename</> <type>text</>)</literal>
12719        </entry>
12720        <entry><type>record</type></entry>
12721        <entry>Return information about a file</entry>
12722       </row>
12723      </tbody>
12724     </tgroup>
12725    </table>
12726
12727    <indexterm>
12728     <primary>pg_ls_dir</primary>
12729    </indexterm>
12730    <para>
12731     <function>pg_ls_dir</> returns all the names in the specified
12732     directory, except the special entries <quote><literal>.</></> and
12733     <quote><literal>..</></>.
12734    </para>
12735
12736    <indexterm>
12737     <primary>pg_read_file</primary>
12738    </indexterm>
12739    <para>
12740     <function>pg_read_file</> returns part of a text file, starting
12741     at the given <parameter>offset</>, returning at most <parameter>length</>
12742     bytes (less if the end of file is reached first).  If <parameter>offset</>
12743     is negative, it is relative to the end of the file.
12744    </para>
12745
12746    <indexterm>
12747     <primary>pg_stat_file</primary>
12748    </indexterm>
12749    <para>
12750     <function>pg_stat_file</> returns a record containing the file
12751     size, last accessed time stamp, last modified time stamp,
12752     last file status change time stamp (Unix platforms only),
12753     file creation time stamp (Windows only), and a <type>boolean</type>
12754     indicating if it is a directory.  Typical usages include:
12755 <programlisting>
12756 SELECT * FROM pg_stat_file('filename');
12757 SELECT (pg_stat_file('filename')).modification;
12758 </programlisting>
12759    </para>
12760
12761    <para>
12762     The functions shown in <xref linkend="functions-advisory-locks"> manage
12763     advisory locks.  For details about proper usage of these functions, see
12764     <xref linkend="advisory-locks">.
12765    </para>
12766
12767    <table id="functions-advisory-locks">
12768     <title>Advisory Lock Functions</title>
12769     <tgroup cols="3">
12770      <thead>
12771       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12772       </row>
12773      </thead>
12774
12775      <tbody>
12776       <row>
12777        <entry>
12778         <literal><function>pg_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
12779        </entry>
12780        <entry><type>void</type></entry>
12781        <entry>Obtain exclusive advisory lock</entry>
12782       </row>
12783       <row>
12784        <entry>
12785         <literal><function>pg_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12786        </entry>
12787        <entry><type>void</type></entry>
12788        <entry>Obtain exclusive advisory lock</entry>
12789       </row>
12790
12791       <row>
12792        <entry>
12793         <literal><function>pg_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12794        </entry>
12795        <entry><type>void</type></entry>
12796        <entry>Obtain shared advisory lock</entry>
12797       </row>
12798       <row>
12799        <entry>
12800         <literal><function>pg_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12801        </entry>
12802        <entry><type>void</type></entry>
12803        <entry>Obtain shared advisory lock</entry>
12804       </row>
12805
12806       <row>
12807        <entry>
12808         <literal><function>pg_try_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
12809        </entry>
12810        <entry><type>boolean</type></entry>
12811        <entry>Obtain exclusive advisory lock if available</entry>
12812       </row>
12813       <row>
12814        <entry>
12815         <literal><function>pg_try_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12816        </entry>
12817        <entry><type>boolean</type></entry>
12818        <entry>Obtain exclusive advisory lock if available</entry>
12819       </row>
12820
12821       <row>
12822        <entry>
12823         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12824        </entry>
12825        <entry><type>boolean</type></entry>
12826        <entry>Obtain shared advisory lock if available</entry>
12827       </row>
12828       <row>
12829        <entry>
12830         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12831        </entry>
12832        <entry><type>boolean</type></entry>
12833        <entry>Obtain shared advisory lock if available</entry>
12834       </row>
12835
12836       <row>
12837        <entry>
12838         <literal><function>pg_advisory_unlock</function>(<parameter>key</> <type>bigint</>)</literal>
12839        </entry>
12840        <entry><type>boolean</type></entry>
12841        <entry>Release an exclusive advisory lock</entry>
12842       </row>
12843       <row>
12844        <entry>
12845         <literal><function>pg_advisory_unlock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12846        </entry>
12847        <entry><type>boolean</type></entry>
12848        <entry>Release an exclusive advisory lock</entry>
12849       </row>
12850
12851       <row>
12852        <entry>
12853         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12854        </entry>
12855        <entry><type>boolean</type></entry>
12856        <entry>Release a shared advisory lock</entry>
12857       </row>
12858       <row>
12859        <entry>
12860         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12861        </entry>
12862        <entry><type>boolean</type></entry>
12863        <entry>Release a shared advisory lock</entry>
12864       </row>
12865
12866       <row>
12867        <entry>
12868         <literal><function>pg_advisory_unlock_all</function>()</literal>
12869        </entry>
12870        <entry><type>void</type></entry>
12871        <entry>Release all advisory locks held by the current session</entry>
12872       </row>
12873
12874      </tbody>
12875     </tgroup>
12876    </table>
12877
12878    <indexterm>
12879     <primary>pg_advisory_lock</primary>
12880    </indexterm>
12881    <para>
12882     <function>pg_advisory_lock</> locks an application-defined resource,
12883     which can be identified either by a single 64-bit key value or two
12884     32-bit key values (note that these two key spaces do not overlap). 
12885     The key type is specified in <literal>pg_locks.objid</>.  If
12886     another session already holds a lock on the same resource, the
12887     function will wait until the resource becomes available.  The lock
12888     is exclusive.  Multiple lock requests stack, so that if the same resource
12889     is locked three times it must be also unlocked three times to be
12890     released for other sessions' use.
12891    </para>
12892
12893    <indexterm>
12894     <primary>pg_advisory_lock_shared</primary>
12895    </indexterm>
12896    <para>
12897     <function>pg_advisory_lock_shared</> works the same as
12898     <function>pg_advisory_lock</>,
12899     except the lock can be shared with other sessions requesting shared locks.
12900     Only would-be exclusive lockers are locked out.
12901    </para>
12902
12903    <indexterm>
12904     <primary>pg_try_advisory_lock</primary>
12905    </indexterm>
12906    <para>
12907     <function>pg_try_advisory_lock</> is similar to
12908     <function>pg_advisory_lock</>, except the function will not wait for the
12909     lock to become available.  It will either obtain the lock immediately and
12910     return <literal>true</>, or return <literal>false</> if the lock cannot be
12911     acquired now.
12912    </para>
12913
12914    <indexterm>
12915     <primary>pg_try_advisory_lock_shared</primary>
12916    </indexterm>
12917    <para>
12918     <function>pg_try_advisory_lock_shared</> works the same as
12919     <function>pg_try_advisory_lock</>, except it attempts to acquire
12920     shared rather than exclusive lock.
12921    </para>
12922
12923    <indexterm>
12924     <primary>pg_advisory_unlock</primary>
12925    </indexterm>
12926    <para>
12927     <function>pg_advisory_unlock</> will release a previously-acquired
12928     exclusive advisory lock.  It
12929     will return <literal>true</> if the lock is successfully released.
12930     If the lock was in fact not held, it will return <literal>false</>,
12931     and in addition, an SQL warning will be raised by the server.
12932    </para>
12933
12934    <indexterm>
12935     <primary>pg_advisory_unlock_shared</primary>
12936    </indexterm>
12937    <para>
12938     <function>pg_advisory_unlock_shared</> works the same as
12939     <function>pg_advisory_unlock</>, 
12940     except to release a shared advisory lock.
12941    </para>
12942
12943    <indexterm>
12944     <primary>pg_advisory_unlock_all</primary>
12945    </indexterm>
12946    <para>
12947     <function>pg_advisory_unlock_all</> will release all advisory locks
12948     held by the current session.  (This function is implicitly invoked
12949     at session end, even if the client disconnects ungracefully.)
12950    </para>
12951
12952   </sect1>
12953
12954   <sect1 id="functions-trigger">
12955    <title>Trigger Functions</title>
12956
12957    <indexterm>
12958      <primary>suppress_redundant_updates_trigger</primary>
12959    </indexterm>
12960
12961    <para>
12962       Currently <productname>PostgreSQL</> provides one built in trigger
12963       function, <function>suppress_redundant_updates_trigger</>, 
12964       which will prevent any update
12965       that does not actually change the data in the row from taking place, in
12966       contrast to the normal behaviour which always performs the update
12967       regardless of whether or not the data has changed. (This normal behaviour
12968       makes updates run faster, since no checking is required, and is also
12969       useful in certain cases.)
12970     </para>
12971
12972     <para>
12973       Ideally, you should normally avoid running updates that don't actually
12974       change the data in the record. Redundant updates can cost considerable
12975       unnecessary time, especially if there are lots of indexes to alter,
12976       and space in dead rows that will eventually have to be vacuumed.
12977       However, detecting such situations in client code is not
12978       always easy, or even possible, and writing expressions to detect
12979       them can be error-prone. An alternative is to use 
12980       <function>suppress_redundant_updates_trigger</>, which will skip
12981       updates that don't change the data. You should use this with care,
12982       however. The trigger takes a small but non-trivial time for each record, 
12983       so if most of the records affected by an update are actually changed,
12984       use of this trigger will actually make the update run slower.
12985     </para>
12986
12987     <para>
12988       The <function>suppress_redundant_updates_trigger</> function can be 
12989       added to a table like this:
12990 <programlisting>
12991 CREATE TRIGGER z_min_update 
12992 BEFORE UPDATE ON tablename
12993 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
12994 </programlisting>
12995       In most cases, you would want to fire this trigger last for each row.
12996       Bearing in mind that triggers fire in name order, you would then
12997       choose a trigger name that comes after the name of any other trigger
12998       you might have on the table.
12999     </para>
13000     <para>
13001        For more information about creating triggers, see
13002         <xref linkend="SQL-CREATETRIGGER">.
13003     </para>
13004   </sect1>
13005 </chapter>