]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
c03863af99aa0d6b5ffae36645e44f15ebd7715e
[postgresql] / doc / src / sgml / func.sgml
1 <!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.445 2008/09/07 01:29:36 momjian Exp $ -->
2
3  <chapter id="functions">
4   <title>Functions and Operators</title>
5
6   <indexterm zone="functions">
7    <primary>function</primary>
8   </indexterm>
9
10   <indexterm zone="functions">
11    <primary>operator</primary>
12   </indexterm>
13
14   <para>
15    <productname>PostgreSQL</productname> provides a large number of
16    functions and operators for the built-in data types.  Users can also
17    define their own functions and operators, as described in
18    <xref linkend="server-programming">.  The
19    <application>psql</application> commands <command>\df</command> and
20    <command>\do</command> can be used to show the list of all actually
21    available functions and operators, respectively.
22   </para>
23
24   <para>
25    If you are concerned about portability then take note that most of
26    the functions and operators described in this chapter, with the
27    exception of the most trivial arithmetic and comparison operators
28    and some explicitly marked functions, are not specified by the
29    <acronym>SQL</acronym> standard. Some of the extended functionality
30    is present in other <acronym>SQL</acronym> database management
31    systems, and in many cases this functionality is compatible and
32    consistent between the various implementations.  This chapter is also
33    not exhaustive;  additional functions appear in relevant sections of 
34    the manual.
35   </para>
36
37
38   <sect1 id="functions-logical">
39    <title>Logical Operators</title>
40
41    <indexterm zone="functions-logical">
42     <primary>operator</primary>
43     <secondary>logical</secondary>
44    </indexterm>
45
46    <indexterm>
47     <primary>Boolean</primary>
48     <secondary>operators</secondary>
49     <see>operators, logical</see>
50    </indexterm>
51
52    <para>
53     The usual logical operators are available:
54
55     <indexterm>
56      <primary>AND (operator)</primary>
57     </indexterm>
58
59     <indexterm>
60      <primary>OR (operator)</primary>
61     </indexterm>
62
63     <indexterm>
64      <primary>NOT (operator)</primary>
65     </indexterm>
66
67     <indexterm>
68      <primary>conjunction</primary>
69     </indexterm>
70
71     <indexterm>
72      <primary>disjunction</primary>
73     </indexterm>
74
75     <indexterm>
76      <primary>negation</primary>
77     </indexterm>
78
79     <simplelist>
80      <member><literal>AND</></member>
81      <member><literal>OR</></member>
82      <member><literal>NOT</></member>
83     </simplelist>
84
85     <acronym>SQL</acronym> uses a three-valued Boolean logic where the null value represents
86     <quote>unknown</quote>.  Observe the following truth tables:
87
88     <informaltable>
89      <tgroup cols="4">
90       <thead>
91        <row>
92         <entry><replaceable>a</replaceable></entry>
93         <entry><replaceable>b</replaceable></entry>
94         <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
95         <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
96        </row>
97       </thead>
98
99       <tbody>
100        <row>
101         <entry>TRUE</entry>
102         <entry>TRUE</entry>
103         <entry>TRUE</entry>
104         <entry>TRUE</entry>
105        </row>
106
107        <row>
108         <entry>TRUE</entry>
109         <entry>FALSE</entry>
110         <entry>FALSE</entry>
111         <entry>TRUE</entry>
112        </row>
113
114        <row>
115         <entry>TRUE</entry>
116         <entry>NULL</entry>
117         <entry>NULL</entry>
118         <entry>TRUE</entry>
119        </row>
120
121        <row>
122         <entry>FALSE</entry>
123         <entry>FALSE</entry>
124         <entry>FALSE</entry>
125         <entry>FALSE</entry>
126        </row>
127
128        <row>
129         <entry>FALSE</entry>
130         <entry>NULL</entry>
131         <entry>FALSE</entry>
132         <entry>NULL</entry>
133        </row>
134
135        <row>
136         <entry>NULL</entry>
137         <entry>NULL</entry>
138         <entry>NULL</entry>
139         <entry>NULL</entry>
140        </row>
141       </tbody>
142      </tgroup>
143     </informaltable>
144
145     <informaltable>
146      <tgroup cols="2">
147       <thead>
148        <row>
149         <entry><replaceable>a</replaceable></entry>
150         <entry>NOT <replaceable>a</replaceable></entry>
151        </row>
152       </thead>
153
154       <tbody>
155        <row>
156         <entry>TRUE</entry>
157         <entry>FALSE</entry>
158        </row>
159
160        <row>
161         <entry>FALSE</entry>
162         <entry>TRUE</entry>
163        </row>
164
165        <row>
166         <entry>NULL</entry>
167         <entry>NULL</entry>
168        </row>
169       </tbody>
170      </tgroup>
171     </informaltable>
172    </para>
173
174    <para>
175     The operators <literal>AND</literal> and <literal>OR</literal> are
176     commutative, that is, you can switch the left and right operand
177     without affecting the result.  But see <xref
178     linkend="syntax-express-eval"> for more information about the
179     order of evaluation of subexpressions.
180    </para>
181   </sect1>
182
183   <sect1 id="functions-comparison">
184    <title>Comparison Operators</title>
185
186    <indexterm zone="functions-comparison">
187     <primary>comparison</primary>
188     <secondary>operators</secondary>
189    </indexterm>
190
191    <para>
192     The usual comparison operators are available, shown in <xref
193     linkend="functions-comparison-table">.
194    </para>
195
196    <table id="functions-comparison-table">
197     <title>Comparison Operators</title>
198     <tgroup cols="2">
199      <thead>
200       <row>
201        <entry>Operator</entry>
202        <entry>Description</entry>
203       </row>
204      </thead>
205
206      <tbody>
207       <row>
208        <entry> <literal>&lt;</literal> </entry>
209        <entry>less than</entry>
210       </row>
211
212       <row>
213        <entry> <literal>&gt;</literal> </entry>
214        <entry>greater than</entry>
215       </row>
216
217       <row>
218        <entry> <literal>&lt;=</literal> </entry>
219        <entry>less than or equal to</entry>
220       </row>
221
222       <row>
223        <entry> <literal>&gt;=</literal> </entry>
224        <entry>greater than or equal to</entry>
225       </row>
226
227       <row>
228        <entry> <literal>=</literal> </entry>
229        <entry>equal</entry>
230       </row>
231
232       <row>
233        <entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
234        <entry>not equal</entry>
235       </row>
236      </tbody>
237     </tgroup>
238    </table>
239
240    <note>
241     <para>
242      The <literal>!=</literal> operator is converted to
243      <literal>&lt;&gt;</literal> in the parser stage.  It is not
244      possible to implement <literal>!=</literal> and
245      <literal>&lt;&gt;</literal> operators that do different things.
246     </para>
247    </note>
248
249    <para>
250     Comparison operators are available for all data types where this
251     makes sense.  All comparison operators are binary operators that
252     return values of type <type>boolean</type>; expressions like
253     <literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
254     no <literal>&lt;</literal> operator to compare a Boolean value with
255     <literal>3</literal>).
256    </para>
257
258    <para>
259     <indexterm>
260      <primary>BETWEEN</primary>
261     </indexterm>
262     In addition to the comparison operators, the special
263     <token>BETWEEN</token> construct is available.
264 <synopsis>
265 <replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
266 </synopsis>
267     is equivalent to
268 <synopsis>
269 <replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
270 </synopsis>
271     Similarly,
272 <synopsis>
273 <replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
274 </synopsis>
275     is equivalent to
276 <synopsis>
277 <replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
278 </synopsis>
279     There is no difference between the two respective forms apart from
280     the <acronym>CPU</acronym> cycles required to rewrite the first one
281     into the second one internally.
282     <indexterm>
283      <primary>BETWEEN SYMMETRIC</primary>
284     </indexterm>
285     <token>BETWEEN SYMMETRIC</> is the same as <literal>BETWEEN</>
286     except there is no requirement that the argument to the left of <literal>AND</> be less than
287     or equal to the argument on the right;  the proper range is automatically determined.
288    </para>
289
290    <para>
291     <indexterm>
292      <primary>IS NULL</primary>
293     </indexterm>
294     <indexterm>
295      <primary>IS NOT NULL</primary>
296     </indexterm>
297     <indexterm>
298      <primary>ISNULL</primary>
299     </indexterm>
300     <indexterm>
301      <primary>NOTNULL</primary>
302     </indexterm>
303     To check whether a value is or is not null, use the constructs
304 <synopsis>
305 <replaceable>expression</replaceable> IS NULL
306 <replaceable>expression</replaceable> IS NOT NULL
307 </synopsis>
308     or the equivalent, but nonstandard, constructs
309 <synopsis>
310 <replaceable>expression</replaceable> ISNULL
311 <replaceable>expression</replaceable> NOTNULL
312 </synopsis>
313     <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
314    </para>
315
316    <para>
317     Do <emphasis>not</emphasis> write
318     <literal><replaceable>expression</replaceable> = NULL</literal>
319     because <literal>NULL</> is not <quote>equal to</quote>
320     <literal>NULL</>.  (The null value represents an unknown value,
321     and it is not known whether two unknown values are equal.) This
322     behavior conforms to the SQL standard.
323    </para>
324
325   <tip>
326    <para>
327     Some applications might expect that
328     <literal><replaceable>expression</replaceable> = NULL</literal>
329     returns true if <replaceable>expression</replaceable> evaluates to
330     the null value.  It is highly recommended that these applications
331     be modified to comply with the SQL standard. However, if that
332     cannot be done the <xref linkend="guc-transform-null-equals">
333     configuration variable is available. If it is enabled,
334     <productname>PostgreSQL</productname> will convert <literal>x =
335     NULL</literal> clauses to <literal>x IS NULL</literal>.  This was
336     the default behavior in <productname>PostgreSQL</productname>
337     releases 6.5 through 7.1.
338    </para>
339   </tip>
340
341   <note>
342    <para>
343     If the <replaceable>expression</replaceable> is row-valued, then
344     <literal>IS NULL</> is true when the row expression itself is null
345     or when all the row's fields are null, while
346     <literal>IS NOT NULL</> is true when the row expression itself is non-null
347     and all the row's fields are non-null.  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>"</>).  The text matching the portion of the pattern
3188     between these markers is returned.
3189    </para>
3190
3191    <para>
3192     Some examples:
3193 <programlisting>
3194 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
3195 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
3196 </programlisting>
3197    </para>
3198   </sect2>
3199
3200   <sect2 id="functions-posix-regexp">
3201    <title><acronym>POSIX</acronym> Regular Expressions</title>
3202
3203    <indexterm zone="functions-posix-regexp">
3204     <primary>regular expression</primary>
3205     <seealso>pattern matching</seealso>
3206    </indexterm>
3207    <indexterm>
3208     <primary>substring</primary>
3209    </indexterm>
3210    <indexterm>
3211     <primary>regexp_replace</primary>
3212    </indexterm>
3213    <indexterm>
3214     <primary>regexp_matches</primary>
3215    </indexterm>
3216    <indexterm>
3217     <primary>regexp_split_to_table</primary>
3218    </indexterm>
3219    <indexterm>
3220     <primary>regexp_split_to_array</primary>
3221    </indexterm>
3222
3223    <para>
3224     <xref linkend="functions-posix-table"> lists the available
3225     operators for pattern matching using POSIX regular expressions.
3226    </para>
3227
3228    <table id="functions-posix-table">
3229     <title>Regular Expression Match Operators</title>
3230
3231     <tgroup cols="3">
3232      <thead>
3233       <row>
3234        <entry>Operator</entry>
3235        <entry>Description</entry>
3236        <entry>Example</entry>
3237       </row>
3238      </thead>
3239
3240       <tbody>
3241        <row>
3242         <entry> <literal>~</literal> </entry>
3243         <entry>Matches regular expression, case sensitive</entry>
3244         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3245        </row>
3246
3247        <row>
3248         <entry> <literal>~*</literal> </entry>
3249         <entry>Matches regular expression, case insensitive</entry>
3250         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3251        </row>
3252
3253        <row>
3254         <entry> <literal>!~</literal> </entry>
3255         <entry>Does not match regular expression, case sensitive</entry>
3256         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3257        </row>
3258
3259        <row>
3260         <entry> <literal>!~*</literal> </entry>
3261         <entry>Does not match regular expression, case insensitive</entry>
3262         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3263        </row>
3264       </tbody>
3265      </tgroup>
3266     </table>
3267
3268     <para>
3269      <acronym>POSIX</acronym> regular expressions provide a more
3270      powerful means for 
3271      pattern matching than the <function>LIKE</function> and
3272      <function>SIMILAR TO</> operators.
3273      Many Unix tools such as <command>egrep</command>,
3274      <command>sed</command>, or <command>awk</command> use a pattern
3275      matching language that is similar to the one described here.
3276     </para>
3277
3278     <para>
3279      A regular expression is a character sequence that is an
3280      abbreviated definition of a set of strings (a <firstterm>regular
3281      set</firstterm>).  A string is said to match a regular expression
3282      if it is a member of the regular set described by the regular
3283      expression.  As with <function>LIKE</function>, pattern characters
3284      match string characters exactly unless they are special characters
3285      in the regular expression language &mdash; but regular expressions use
3286      different special characters than <function>LIKE</function> does.
3287      Unlike <function>LIKE</function> patterns, a
3288      regular expression is allowed to match anywhere within a string, unless
3289      the regular expression is explicitly anchored to the beginning or
3290      end of the string.
3291     </para>
3292
3293     <para>
3294      Some examples:
3295 <programlisting>
3296 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
3297 'abc' ~ '^a'     <lineannotation>true</lineannotation>
3298 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
3299 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3300 </programlisting>
3301     </para>
3302
3303     <para>
3304      The <acronym>POSIX</acronym> pattern language is described in much
3305      greater detail below.
3306     </para>
3307
3308     <para>
3309      The <function>substring</> function with two parameters,
3310      <function>substring(<replaceable>string</replaceable> from
3311      <replaceable>pattern</replaceable>)</function>, provides extraction of a
3312      substring
3313      that matches a POSIX regular expression pattern.  It returns null if
3314      there is no match, otherwise the portion of the text that matched the
3315      pattern.  But if the pattern contains any parentheses, the portion
3316      of the text that matched the first parenthesized subexpression (the
3317      one whose left parenthesis comes first) is
3318      returned.  You can put parentheses around the whole expression
3319      if you want to use parentheses within it without triggering this
3320      exception.  If you need parentheses in the pattern before the
3321      subexpression you want to extract, see the non-capturing parentheses
3322      described below.
3323     </para>
3324
3325    <para>
3326     Some examples:
3327 <programlisting>
3328 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
3329 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
3330 </programlisting>
3331    </para>
3332
3333     <para>
3334      The <function>regexp_replace</> function provides substitution of
3335      new text for substrings that match POSIX regular expression patterns.
3336      It has the syntax
3337      <function>regexp_replace</function>(<replaceable>source</>,
3338      <replaceable>pattern</>, <replaceable>replacement</>
3339      <optional>, <replaceable>flags</> </optional>).
3340      The <replaceable>source</> string is returned unchanged if
3341      there is no match to the <replaceable>pattern</>.  If there is a
3342      match, the <replaceable>source</> string is returned with the
3343      <replaceable>replacement</> string substituted for the matching
3344      substring.  The <replaceable>replacement</> string can contain
3345      <literal>\</><replaceable>n</>, where <replaceable>n</> is <literal>1</>
3346      through <literal>9</>, to indicate that the source substring matching the
3347      <replaceable>n</>'th parenthesized subexpression of the pattern should be
3348      inserted, and it can contain <literal>\&amp;</> to indicate that the
3349      substring matching the entire pattern should be inserted.  Write
3350      <literal>\\</> if you need to put a literal backslash in the replacement
3351      text.  (As always, remember to double backslashes written in literal
3352      constant strings, assuming escape string syntax is used.)
3353      The <replaceable>flags</> parameter is an optional text
3354      string containing zero or more single-letter flags that change the
3355      function's behavior.  Flag <literal>i</> specifies case-insensitive
3356      matching, while flag <literal>g</> specifies replacement of each matching
3357      substring rather than only the first one.  Other supported flags are
3358      described in <xref linkend="posix-embedded-options-table">.
3359     </para>
3360
3361    <para>
3362     Some examples:
3363 <programlisting>
3364 regexp_replace('foobarbaz', 'b..', 'X')
3365                                    <lineannotation>fooXbaz</lineannotation>
3366 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3367                                    <lineannotation>fooXX</lineannotation>
3368 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3369                                    <lineannotation>fooXarYXazY</lineannotation>
3370 </programlisting>
3371    </para>
3372
3373     <para>
3374      The <function>regexp_matches</> function returns all of the captured
3375      substrings resulting from matching a POSIX regular expression pattern.
3376      It has the syntax
3377      <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3378      <optional>, <replaceable>flags</> </optional>).
3379      If there is no match to the <replaceable>pattern</>, the function returns
3380      no rows.  If there is a match, the function returns a text array whose
3381      <replaceable>n</>'th element is the substring matching the
3382      <replaceable>n</>'th parenthesized subexpression of the pattern
3383      (not counting <quote>non-capturing</> parentheses; see below for
3384      details).  If the pattern does not contain any parenthesized
3385      subexpressions, then the result is a single-element text array containing
3386      the substring matching the whole pattern.
3387      The <replaceable>flags</> parameter is an optional text
3388      string containing zero or more single-letter flags that change the
3389      function's behavior.  Flag <literal>g</> causes the function to find
3390      each match in the string, not only the first one, and return a row for
3391      each such match.  Other supported
3392      flags are described in <xref linkend="posix-embedded-options-table">.
3393     </para>
3394
3395    <para>
3396     Some examples:
3397 <programlisting>
3398 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3399  regexp_matches 
3400 ----------------
3401  {bar,beque}
3402 (1 row)
3403
3404 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3405  regexp_matches 
3406 ----------------
3407  {bar,beque}
3408  {bazil,barf}
3409 (2 rows)
3410
3411 SELECT regexp_matches('foobarbequebaz', 'barbeque');
3412  regexp_matches 
3413 ----------------
3414  {barbeque}
3415 (1 row)
3416 </programlisting>
3417    </para>
3418
3419     <para>
3420      The <function>regexp_split_to_table</> function splits a string using a POSIX
3421      regular expression pattern as a delimiter.  It has the syntax
3422      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
3423      <optional>, <replaceable>flags</> </optional>).
3424      If there is no match to the <replaceable>pattern</>, the function returns the
3425      <replaceable>string</>.  If there is at least one match, for each match it returns
3426      the text from the end of the last match (or the beginning of the string)
3427      to the beginning of the match.  When there are no more matches, it
3428      returns the text from the end of the last match to the end of the string.
3429      The <replaceable>flags</> parameter is an optional text string containing
3430      zero or more single-letter flags that change the function's behavior.
3431      <function>regexp_split_to_table</function> supports the flags described in
3432      <xref linkend="posix-embedded-options-table">.
3433     </para>
3434
3435     <para>
3436      The <function>regexp_split_to_array</> function behaves the same as
3437      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
3438      returns its result as an array of <type>text</>.  It has the syntax
3439      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
3440      <optional>, <replaceable>flags</> </optional>).
3441      The parameters are the same as for <function>regexp_split_to_table</>.
3442     </para>
3443
3444    <para>
3445     Some examples:
3446 <programlisting>
3447
3448 SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\\s+') AS foo;
3449   foo   
3450 --------
3451  the    
3452  quick  
3453  brown  
3454  fox    
3455  jumped 
3456  over   
3457  the    
3458  lazy   
3459  dog    
3460 (9 rows)
3461
3462 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
3463               regexp_split_to_array             
3464 ------------------------------------------------
3465  {the,quick,brown,fox,jumped,over,the,lazy,dog}
3466 (1 row)
3467
3468 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
3469  foo 
3470 -----
3471  t         
3472  h         
3473  e         
3474  q         
3475  u         
3476  i         
3477  c         
3478  k         
3479  b         
3480  r         
3481  o         
3482  w         
3483  n         
3484  f         
3485  o         
3486  x         
3487 (16 rows)
3488 </programlisting>
3489    </para>
3490
3491    <para>
3492     As the last example demonstrates, the regexp split functions ignore
3493     zero-length matches that occur at the start or end of the string
3494     or immediately after a previous match.  This is contrary to the strict
3495     definition of regexp matching that is implemented by
3496     <function>regexp_matches</>, but is usually the most convenient behavior
3497     in practice.  Other software systems such as Perl use similar definitions.
3498    </para>
3499
3500 <!-- derived from the re_syntax.n man page -->
3501
3502    <sect3 id="posix-syntax-details">
3503     <title>Regular Expression Details</title>
3504
3505    <para>
3506     <productname>PostgreSQL</productname>'s regular expressions are implemented
3507     using a package written by Henry Spencer.  Much of
3508     the description of regular expressions below is copied verbatim from his
3509     manual entry.
3510    </para>
3511
3512    <para>
3513     Regular expressions (<acronym>RE</acronym>s), as defined in
3514     <acronym>POSIX</acronym> 1003.2, come in two forms:
3515     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
3516     (roughly those of <command>egrep</command>), and
3517     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
3518     (roughly those of <command>ed</command>).
3519     <productname>PostgreSQL</productname> supports both forms, and
3520     also implements some extensions
3521     that are not in the POSIX standard, but have become widely used anyway
3522     due to their availability in programming languages such as Perl and Tcl.
3523     <acronym>RE</acronym>s using these non-POSIX extensions are called
3524     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
3525     in this documentation.  AREs are almost an exact superset of EREs,
3526     but BREs have several notational incompatibilities (as well as being
3527     much more limited).
3528     We first describe the ARE and ERE forms, noting features that apply
3529     only to AREs, and then describe how BREs differ.
3530    </para>
3531
3532    <note>
3533     <para>
3534      The form of regular expressions accepted by
3535      <productname>PostgreSQL</> can be chosen by setting the <xref
3536      linkend="guc-regex-flavor"> run-time parameter.  The usual
3537      setting is <literal>advanced</>, but one might choose
3538      <literal>extended</> for maximum backwards compatibility with
3539      pre-7.4 releases of <productname>PostgreSQL</>.
3540     </para>
3541    </note>
3542
3543    <para>
3544     A regular expression is defined as one or more
3545     <firstterm>branches</firstterm>, separated by
3546     <literal>|</literal>.  It matches anything that matches one of the
3547     branches.
3548    </para>
3549
3550    <para>
3551     A branch is zero or more <firstterm>quantified atoms</> or
3552     <firstterm>constraints</>, concatenated.
3553     It matches a match for the first, followed by a match for the second, etc;
3554     an empty branch matches the empty string.
3555    </para>
3556
3557    <para>
3558     A quantified atom is an <firstterm>atom</> possibly followed
3559     by a single <firstterm>quantifier</>.
3560     Without a quantifier, it matches a match for the atom.
3561     With a quantifier, it can match some number of matches of the atom.
3562     An <firstterm>atom</firstterm> can be any of the possibilities
3563     shown in <xref linkend="posix-atoms-table">.
3564     The possible quantifiers and their meanings are shown in
3565     <xref linkend="posix-quantifiers-table">.
3566    </para>
3567
3568    <para>
3569     A <firstterm>constraint</> matches an empty string, but matches only when
3570     specific conditions are met.  A constraint can be used where an atom
3571     could be used, except it cannot be followed by a quantifier.
3572     The simple constraints are shown in
3573     <xref linkend="posix-constraints-table">;
3574     some more constraints are described later.
3575    </para>
3576
3577
3578    <table id="posix-atoms-table">
3579     <title>Regular Expression Atoms</title>
3580
3581     <tgroup cols="2">
3582      <thead>
3583       <row>
3584        <entry>Atom</entry>
3585        <entry>Description</entry>
3586       </row>
3587      </thead>
3588
3589       <tbody>
3590        <row>
3591        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3592        <entry> (where <replaceable>re</> is any regular expression)
3593        matches a match for
3594        <replaceable>re</>, with the match noted for possible reporting </entry>
3595        </row>
3596
3597        <row>
3598        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3599        <entry> as above, but the match is not noted for reporting
3600        (a <quote>non-capturing</> set of parentheses)
3601        (AREs only) </entry>
3602        </row>
3603
3604        <row>
3605        <entry> <literal>.</> </entry>
3606        <entry> matches any single character </entry>
3607        </row>
3608
3609        <row>
3610        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
3611        <entry> a <firstterm>bracket expression</>,
3612        matching any one of the <replaceable>chars</> (see
3613        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
3614        </row>
3615
3616        <row>
3617        <entry> <literal>\</><replaceable>k</> </entry>
3618        <entry> (where <replaceable>k</> is a non-alphanumeric character)
3619        matches that character taken as an ordinary character,
3620        e.g. <literal>\\</> matches a backslash character </entry>
3621        </row>
3622
3623        <row>
3624        <entry> <literal>\</><replaceable>c</> </entry>
3625        <entry> where <replaceable>c</> is alphanumeric
3626        (possibly followed by other characters)
3627        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
3628        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
3629        </row>
3630
3631        <row>
3632        <entry> <literal>{</> </entry>
3633        <entry> when followed by a character other than a digit,
3634        matches the left-brace character <literal>{</>;
3635        when followed by a digit, it is the beginning of a
3636        <replaceable>bound</> (see below) </entry>
3637        </row>
3638
3639        <row>
3640        <entry> <replaceable>x</> </entry>
3641        <entry> where <replaceable>x</> is a single character with no other
3642        significance, matches that character </entry>
3643        </row>
3644       </tbody>
3645      </tgroup>
3646     </table>
3647
3648    <para>
3649     An RE cannot end with <literal>\</>.
3650    </para>
3651
3652    <note>
3653     <para>
3654      Remember that the backslash (<literal>\</literal>) already has a special
3655      meaning in <productname>PostgreSQL</> string literals.
3656      To write a pattern constant that contains a backslash,
3657      you must write two backslashes in the statement, assuming escape
3658      string syntax is used (see <xref linkend="sql-syntax-strings">).
3659     </para>
3660    </note>
3661
3662    <table id="posix-quantifiers-table">
3663     <title>Regular Expression Quantifiers</title>
3664
3665     <tgroup cols="2">
3666      <thead>
3667       <row>
3668        <entry>Quantifier</entry>
3669        <entry>Matches</entry>
3670       </row>
3671      </thead>
3672
3673       <tbody>
3674        <row>
3675        <entry> <literal>*</> </entry>
3676        <entry> a sequence of 0 or more matches of the atom </entry>
3677        </row>
3678
3679        <row>
3680        <entry> <literal>+</> </entry>
3681        <entry> a sequence of 1 or more matches of the atom </entry>
3682        </row>
3683
3684        <row>
3685        <entry> <literal>?</> </entry>
3686        <entry> a sequence of 0 or 1 matches of the atom </entry>
3687        </row>
3688
3689        <row>
3690        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
3691        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
3692        </row>
3693
3694        <row>
3695        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
3696        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
3697        </row>
3698
3699        <row>
3700        <entry>
3701        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3702        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
3703        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
3704        <replaceable>n</> </entry>
3705        </row>
3706
3707        <row>
3708        <entry> <literal>*?</> </entry>
3709        <entry> non-greedy version of <literal>*</> </entry>
3710        </row>
3711
3712        <row>
3713        <entry> <literal>+?</> </entry>
3714        <entry> non-greedy version of <literal>+</> </entry>
3715        </row>
3716
3717        <row>
3718        <entry> <literal>??</> </entry>
3719        <entry> non-greedy version of <literal>?</> </entry>
3720        </row>
3721
3722        <row>
3723        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
3724        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
3725        </row>
3726
3727        <row>
3728        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
3729        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
3730        </row>
3731
3732        <row>
3733        <entry>
3734        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
3735        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3736        </row>
3737       </tbody>
3738      </tgroup>
3739     </table>
3740
3741    <para>
3742     The forms using <literal>{</><replaceable>...</><literal>}</>
3743     are known as <firstterm>bounds</>.
3744     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
3745     unsigned decimal integers with permissible values from 0 to 255 inclusive.
3746    </para>
3747
3748     <para>
3749      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
3750      same possibilities as their corresponding normal (<firstterm>greedy</>)
3751      counterparts, but prefer the smallest number rather than the largest
3752      number of matches.
3753      See <xref linkend="posix-matching-rules"> for more detail.
3754    </para>
3755
3756    <note>
3757     <para>
3758      A quantifier cannot immediately follow another quantifier.
3759      A quantifier cannot
3760      begin an expression or subexpression or follow
3761      <literal>^</literal> or <literal>|</literal>.
3762     </para>
3763    </note>
3764
3765    <table id="posix-constraints-table">
3766     <title>Regular Expression Constraints</title>
3767
3768     <tgroup cols="2">
3769      <thead>
3770       <row>
3771        <entry>Constraint</entry>
3772        <entry>Description</entry>
3773       </row>
3774      </thead>
3775
3776       <tbody>
3777        <row>
3778        <entry> <literal>^</> </entry>
3779        <entry> matches at the beginning of the string </entry>
3780        </row>
3781
3782        <row>
3783        <entry> <literal>$</> </entry>
3784        <entry> matches at the end of the string </entry>
3785        </row>
3786
3787        <row>
3788        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
3789        <entry> <firstterm>positive lookahead</> matches at any point
3790        where a substring matching <replaceable>re</> begins
3791        (AREs only) </entry>
3792        </row>
3793
3794        <row>
3795        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
3796        <entry> <firstterm>negative lookahead</> matches at any point
3797        where no substring matching <replaceable>re</> begins
3798        (AREs only) </entry>
3799        </row>
3800       </tbody>
3801      </tgroup>
3802     </table>
3803
3804    <para>
3805     Lookahead constraints cannot contain <firstterm>back references</>
3806     (see <xref linkend="posix-escape-sequences">),
3807     and all parentheses within them are considered non-capturing.
3808    </para>
3809    </sect3>
3810
3811    <sect3 id="posix-bracket-expressions">
3812     <title>Bracket Expressions</title>
3813
3814    <para>
3815     A <firstterm>bracket expression</firstterm> is a list of
3816     characters enclosed in <literal>[]</literal>.  It normally matches
3817     any single character from the list (but see below).  If the list
3818     begins with <literal>^</literal>, it matches any single character
3819     <emphasis>not</> from the rest of the list.
3820     If two characters
3821     in the list are separated by <literal>-</literal>, this is
3822     shorthand for the full range of characters between those two
3823     (inclusive) in the collating sequence,
3824     e.g. <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
3825     any decimal digit.  It is illegal for two ranges to share an
3826     endpoint, e.g.  <literal>a-c-e</literal>.  Ranges are very
3827     collating-sequence-dependent, so portable programs should avoid
3828     relying on them.
3829    </para>
3830
3831    <para>
3832     To include a literal <literal>]</literal> in the list, make it the
3833     first character (following a possible <literal>^</literal>).  To
3834     include a literal <literal>-</literal>, make it the first or last
3835     character, or the second endpoint of a range.  To use a literal
3836     <literal>-</literal> as the first endpoint of a range, enclose it
3837     in <literal>[.</literal> and <literal>.]</literal> to make it a
3838     collating element (see below).  With the exception of these characters,
3839     some combinations using <literal>[</literal>
3840     (see next paragraphs), and escapes (AREs only), all other special
3841     characters lose their special significance within a bracket expression.
3842     In particular, <literal>\</literal> is not special when following
3843     ERE or BRE rules, though it is special (as introducing an escape)
3844     in AREs.
3845    </para>
3846
3847    <para>
3848     Within a bracket expression, a collating element (a character, a
3849     multiple-character sequence that collates as if it were a single
3850     character, or a collating-sequence name for either) enclosed in
3851     <literal>[.</literal> and <literal>.]</literal> stands for the
3852     sequence of characters of that collating element.  The sequence is
3853     a single element of the bracket expression's list.  A bracket
3854     expression containing a multiple-character collating element can thus
3855     match more than one character, e.g. if the collating sequence
3856     includes a <literal>ch</literal> collating element, then the RE
3857     <literal>[[.ch.]]*c</literal> matches the first five characters of
3858     <literal>chchcc</literal>.
3859    </para>
3860
3861    <note>
3862     <para>
3863      <productname>PostgreSQL</> currently has no multicharacter collating
3864      elements. This information describes possible future behavior.
3865     </para>
3866    </note>
3867
3868    <para>
3869     Within a bracket expression, a collating element enclosed in
3870     <literal>[=</literal> and <literal>=]</literal> is an equivalence
3871     class, standing for the sequences of characters of all collating
3872     elements equivalent to that one, including itself.  (If there are
3873     no other equivalent collating elements, the treatment is as if the
3874     enclosing delimiters were <literal>[.</literal> and
3875     <literal>.]</literal>.)  For example, if <literal>o</literal> and
3876     <literal>^</literal> are the members of an equivalence class, then
3877     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
3878     <literal>[o^]</literal> are all synonymous.  An equivalence class
3879     cannot be an endpoint of a range.
3880    </para>
3881
3882    <para>
3883     Within a bracket expression, the name of a character class
3884     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
3885     for the list of all characters belonging to that class.  Standard
3886     character class names are: <literal>alnum</literal>,
3887     <literal>alpha</literal>, <literal>blank</literal>,
3888     <literal>cntrl</literal>, <literal>digit</literal>,
3889     <literal>graph</literal>, <literal>lower</literal>,
3890     <literal>print</literal>, <literal>punct</literal>,
3891     <literal>space</literal>, <literal>upper</literal>,
3892     <literal>xdigit</literal>.  These stand for the character classes
3893     defined in
3894     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
3895     A locale can provide others.  A character class cannot be used as
3896     an endpoint of a range.
3897    </para>
3898
3899    <para>
3900     There are two special cases of bracket expressions:  the bracket
3901     expressions <literal>[[:&lt;:]]</literal> and
3902     <literal>[[:&gt;:]]</literal> are constraints,
3903     matching empty strings at the beginning
3904     and end of a word respectively.  A word is defined as a sequence
3905     of word characters that is neither preceded nor followed by word
3906     characters.  A word character is an <literal>alnum</> character (as
3907     defined by
3908     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
3909     or an underscore.  This is an extension, compatible with but not
3910     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
3911     caution in software intended to be portable to other systems.
3912     The constraint escapes described below are usually preferable (they
3913     are no more standard, but are certainly easier to type).
3914    </para>
3915    </sect3>
3916
3917    <sect3 id="posix-escape-sequences">
3918     <title>Regular Expression Escapes</title>
3919
3920    <para>
3921     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
3922     followed by an alphanumeric character. Escapes come in several varieties:
3923     character entry, class shorthands, constraint escapes, and back references.
3924     A <literal>\</> followed by an alphanumeric character but not constituting
3925     a valid escape is illegal in AREs.
3926     In EREs, there are no escapes: outside a bracket expression,
3927     a <literal>\</> followed by an alphanumeric character merely stands for
3928     that character as an ordinary character, and inside a bracket expression,
3929     <literal>\</> is an ordinary character.
3930     (The latter is the one actual incompatibility between EREs and AREs.)
3931    </para>
3932
3933    <para>
3934     <firstterm>Character-entry escapes</> exist to make it easier to specify
3935     non-printing and otherwise inconvenient characters in REs.  They are
3936     shown in <xref linkend="posix-character-entry-escapes-table">.
3937    </para>
3938
3939    <para>
3940     <firstterm>Class-shorthand escapes</> provide shorthands for certain
3941     commonly-used character classes.  They are
3942     shown in <xref linkend="posix-class-shorthand-escapes-table">.
3943    </para>
3944
3945    <para>
3946     A <firstterm>constraint escape</> is a constraint,
3947     matching the empty string if specific conditions are met,
3948     written as an escape.  They are
3949     shown in <xref linkend="posix-constraint-escapes-table">.
3950    </para>
3951
3952    <para>
3953     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
3954     same string matched by the previous parenthesized subexpression specified
3955     by the number <replaceable>n</>
3956     (see <xref linkend="posix-constraint-backref-table">).  For example,
3957     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
3958     but not <literal>bc</> or <literal>cb</>.
3959     The subexpression must entirely precede the back reference in the RE.
3960     Subexpressions are numbered in the order of their leading parentheses.
3961     Non-capturing parentheses do not define subexpressions.
3962    </para>
3963
3964    <note>
3965     <para>
3966      Keep in mind that an escape's leading <literal>\</> will need to be
3967      doubled when entering the pattern as an SQL string constant.  For example:
3968 <programlisting>
3969 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
3970 </programlisting>
3971     </para>
3972    </note>
3973
3974    <table id="posix-character-entry-escapes-table">
3975     <title>Regular Expression Character-Entry Escapes</title>
3976
3977     <tgroup cols="2">
3978      <thead>
3979       <row>
3980        <entry>Escape</entry>
3981        <entry>Description</entry>
3982       </row>
3983      </thead>
3984
3985       <tbody>
3986        <row>
3987        <entry> <literal>\a</> </entry>
3988        <entry> alert (bell) character, as in C </entry>
3989        </row>
3990
3991        <row>
3992        <entry> <literal>\b</> </entry>
3993        <entry> backspace, as in C </entry>
3994        </row>
3995
3996        <row>
3997        <entry> <literal>\B</> </entry>
3998        <entry> synonym for <literal>\</> to help reduce the need for backslash
3999        doubling </entry>
4000        </row>
4001
4002        <row>
4003        <entry> <literal>\c</><replaceable>X</> </entry>
4004        <entry> (where <replaceable>X</> is any character) the character whose
4005        low-order 5 bits are the same as those of
4006        <replaceable>X</>, and whose other bits are all zero </entry>
4007        </row>
4008
4009        <row>
4010        <entry> <literal>\e</> </entry>
4011        <entry> the character whose collating-sequence name
4012        is <literal>ESC</>,
4013        or failing that, the character with octal value 033 </entry>
4014        </row>
4015
4016        <row>
4017        <entry> <literal>\f</> </entry>
4018        <entry> form feed, as in C </entry>
4019        </row>
4020
4021        <row>
4022        <entry> <literal>\n</> </entry>
4023        <entry> newline, as in C </entry>
4024        </row>
4025
4026        <row>
4027        <entry> <literal>\r</> </entry>
4028        <entry> carriage return, as in C </entry>
4029        </row>
4030
4031        <row>
4032        <entry> <literal>\t</> </entry>
4033        <entry> horizontal tab, as in C </entry>
4034        </row>
4035
4036        <row>
4037        <entry> <literal>\u</><replaceable>wxyz</> </entry>
4038        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4039        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4040        in the local byte ordering </entry>
4041        </row>
4042
4043        <row>
4044        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4045        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4046        digits)
4047        reserved for a somewhat-hypothetical Unicode extension to 32 bits
4048        </entry> 
4049        </row>
4050
4051        <row>
4052        <entry> <literal>\v</> </entry>
4053        <entry> vertical tab, as in C </entry>
4054        </row>
4055
4056        <row>
4057        <entry> <literal>\x</><replaceable>hhh</> </entry>
4058        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4059        digits)
4060        the character whose hexadecimal value is
4061        <literal>0x</><replaceable>hhh</>
4062        (a single character no matter how many hexadecimal digits are used)
4063        </entry>
4064        </row>
4065
4066        <row>
4067        <entry> <literal>\0</> </entry>
4068        <entry> the character whose value is <literal>0</> </entry>
4069        </row>
4070
4071        <row>
4072        <entry> <literal>\</><replaceable>xy</> </entry>
4073        <entry> (where <replaceable>xy</> is exactly two octal digits,
4074        and is not a <firstterm>back reference</>)
4075        the character whose octal value is
4076        <literal>0</><replaceable>xy</> </entry>
4077        </row>
4078
4079        <row>
4080        <entry> <literal>\</><replaceable>xyz</> </entry>
4081        <entry> (where <replaceable>xyz</> is exactly three octal digits,
4082        and is not a <firstterm>back reference</>)
4083        the character whose octal value is
4084        <literal>0</><replaceable>xyz</> </entry>
4085        </row>
4086       </tbody>
4087      </tgroup>
4088     </table>
4089
4090    <para>
4091     Hexadecimal digits are <literal>0</>-<literal>9</>,
4092     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4093     Octal digits are <literal>0</>-<literal>7</>.
4094    </para>
4095
4096    <para>
4097     The character-entry escapes are always taken as ordinary characters.
4098     For example, <literal>\135</> is <literal>]</> in ASCII, but
4099     <literal>\135</> does not terminate a bracket expression.
4100    </para>
4101
4102    <table id="posix-class-shorthand-escapes-table">
4103     <title>Regular Expression Class-Shorthand Escapes</title>
4104
4105     <tgroup cols="2">
4106      <thead>
4107       <row>
4108        <entry>Escape</entry>
4109        <entry>Description</entry>
4110       </row>
4111      </thead>
4112
4113       <tbody>
4114        <row>
4115        <entry> <literal>\d</> </entry>
4116        <entry> <literal>[[:digit:]]</> </entry>
4117        </row>
4118
4119        <row>
4120        <entry> <literal>\s</> </entry>
4121        <entry> <literal>[[:space:]]</> </entry>
4122        </row>
4123
4124        <row>
4125        <entry> <literal>\w</> </entry>
4126        <entry> <literal>[[:alnum:]_]</>
4127        (note underscore is included) </entry>
4128        </row>
4129
4130        <row>
4131        <entry> <literal>\D</> </entry>
4132        <entry> <literal>[^[:digit:]]</> </entry>
4133        </row>
4134
4135        <row>
4136        <entry> <literal>\S</> </entry>
4137        <entry> <literal>[^[:space:]]</> </entry>
4138        </row>
4139
4140        <row>
4141        <entry> <literal>\W</> </entry>
4142        <entry> <literal>[^[:alnum:]_]</>
4143        (note underscore is included) </entry>
4144        </row>
4145       </tbody>
4146      </tgroup>
4147     </table>
4148
4149    <para>
4150     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4151     and <literal>\w</> lose their outer brackets,
4152     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4153     (So, for example, <literal>[a-c\d]</> is equivalent to
4154     <literal>[a-c[:digit:]]</>.
4155     Also, <literal>[a-c\D]</>, which is equivalent to
4156     <literal>[a-c^[:digit:]]</>, is illegal.)
4157    </para>
4158
4159    <table id="posix-constraint-escapes-table">
4160     <title>Regular Expression Constraint Escapes</title>
4161
4162     <tgroup cols="2">
4163      <thead>
4164       <row>
4165        <entry>Escape</entry>
4166        <entry>Description</entry>
4167       </row>
4168      </thead>
4169
4170       <tbody>
4171        <row>
4172        <entry> <literal>\A</> </entry>
4173        <entry> matches only at the beginning of the string
4174        (see <xref linkend="posix-matching-rules"> for how this differs from
4175        <literal>^</>) </entry>
4176        </row>
4177
4178        <row>
4179        <entry> <literal>\m</> </entry>
4180        <entry> matches only at the beginning of a word </entry>
4181        </row>
4182
4183        <row>
4184        <entry> <literal>\M</> </entry>
4185        <entry> matches only at the end of a word </entry>
4186        </row>
4187
4188        <row>
4189        <entry> <literal>\y</> </entry>
4190        <entry> matches only at the beginning or end of a word </entry>
4191        </row>
4192
4193        <row>
4194        <entry> <literal>\Y</> </entry>
4195        <entry> matches only at a point that is not the beginning or end of a
4196        word </entry>
4197        </row>
4198
4199        <row>
4200        <entry> <literal>\Z</> </entry>
4201        <entry> matches only at the end of the string
4202        (see <xref linkend="posix-matching-rules"> for how this differs from
4203        <literal>$</>) </entry>
4204        </row>
4205       </tbody>
4206      </tgroup>
4207     </table>
4208
4209    <para>
4210     A word is defined as in the specification of
4211     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4212     Constraint escapes are illegal within bracket expressions.
4213    </para>
4214
4215    <table id="posix-constraint-backref-table">
4216     <title>Regular Expression Back References</title>
4217
4218     <tgroup cols="2">
4219      <thead>
4220       <row>
4221        <entry>Escape</entry>
4222        <entry>Description</entry>
4223       </row>
4224      </thead>
4225
4226       <tbody>
4227        <row>
4228        <entry> <literal>\</><replaceable>m</> </entry>
4229        <entry> (where <replaceable>m</> is a nonzero digit)
4230        a back reference to the <replaceable>m</>'th subexpression </entry>
4231        </row>
4232
4233        <row>
4234        <entry> <literal>\</><replaceable>mnn</> </entry>
4235        <entry> (where <replaceable>m</> is a nonzero digit, and
4236        <replaceable>nn</> is some more digits, and the decimal value
4237        <replaceable>mnn</> is not greater than the number of closing capturing
4238        parentheses seen so far) 
4239        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4240        </row>
4241       </tbody>
4242      </tgroup>
4243     </table>
4244
4245    <note>
4246     <para>
4247      There is an inherent historical ambiguity between octal character-entry 
4248      escapes and back references, which is resolved by heuristics,
4249      as hinted at above.
4250      A leading zero always indicates an octal escape.
4251      A single non-zero digit, not followed by another digit,
4252      is always taken as a back reference.
4253      A multidigit sequence not starting with a zero is taken as a back 
4254      reference if it comes after a suitable subexpression
4255      (i.e. the number is in the legal range for a back reference),
4256      and otherwise is taken as octal.
4257     </para>
4258    </note>
4259    </sect3>
4260
4261    <sect3 id="posix-metasyntax">
4262     <title>Regular Expression Metasyntax</title>
4263
4264    <para>
4265     In addition to the main syntax described above, there are some special
4266     forms and miscellaneous syntactic facilities available.
4267    </para>
4268
4269    <para>
4270     Normally the flavor of RE being used is determined by
4271     <varname>regex_flavor</>.
4272     However, this can be overridden by a <firstterm>director</> prefix.
4273     If an RE begins with <literal>***:</>,
4274     the rest of the RE is taken as an ARE regardless of
4275     <varname>regex_flavor</>.
4276     If an RE begins with <literal>***=</>,
4277     the rest of the RE is taken to be a literal string,
4278     with all characters considered ordinary characters.
4279    </para>
4280
4281    <para>
4282     An ARE can begin with <firstterm>embedded options</>:
4283     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4284     (where <replaceable>xyz</> is one or more alphabetic characters)
4285     specifies options affecting the rest of the RE.
4286     These options override any previously determined options (including
4287     both the RE flavor and case sensitivity).
4288     The available option letters are
4289     shown in <xref linkend="posix-embedded-options-table">.
4290    </para>
4291
4292    <table id="posix-embedded-options-table">
4293     <title>ARE Embedded-Option Letters</title>
4294
4295     <tgroup cols="2">
4296      <thead>
4297       <row>
4298        <entry>Option</entry>
4299        <entry>Description</entry>
4300       </row>
4301      </thead>
4302
4303       <tbody>
4304        <row>
4305        <entry> <literal>b</> </entry>
4306        <entry> rest of RE is a BRE </entry>
4307        </row>
4308
4309        <row>
4310        <entry> <literal>c</> </entry>
4311        <entry> case-sensitive matching (overrides operator type) </entry>
4312        </row>
4313
4314        <row>
4315        <entry> <literal>e</> </entry>
4316        <entry> rest of RE is an ERE </entry>
4317        </row>
4318
4319        <row>
4320        <entry> <literal>i</> </entry>
4321        <entry> case-insensitive matching (see
4322        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4323        </row>
4324
4325        <row>
4326        <entry> <literal>m</> </entry>
4327        <entry> historical synonym for <literal>n</> </entry>
4328        </row>
4329
4330        <row>
4331        <entry> <literal>n</> </entry>
4332        <entry> newline-sensitive matching (see
4333        <xref linkend="posix-matching-rules">) </entry>
4334        </row>
4335
4336        <row>
4337        <entry> <literal>p</> </entry>
4338        <entry> partial newline-sensitive matching (see
4339        <xref linkend="posix-matching-rules">) </entry>
4340        </row>
4341
4342        <row>
4343        <entry> <literal>q</> </entry>
4344        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4345        characters </entry>
4346        </row>
4347
4348        <row>
4349        <entry> <literal>s</> </entry>
4350        <entry> non-newline-sensitive matching (default) </entry>
4351        </row>
4352
4353        <row>
4354        <entry> <literal>t</> </entry>
4355        <entry> tight syntax (default; see below) </entry>
4356        </row>
4357
4358        <row>
4359        <entry> <literal>w</> </entry>
4360        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4361        (see <xref linkend="posix-matching-rules">) </entry>
4362        </row>
4363
4364        <row>
4365        <entry> <literal>x</> </entry>
4366        <entry> expanded syntax (see below) </entry>
4367        </row>
4368       </tbody>
4369      </tgroup>
4370     </table>
4371
4372    <para>
4373     Embedded options take effect at the <literal>)</> terminating the sequence.
4374     They can appear only at the start of an ARE (after the
4375     <literal>***:</> director if any).
4376    </para>
4377
4378    <para>
4379     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4380     characters are significant, there is an <firstterm>expanded</> syntax,
4381     available by specifying the embedded <literal>x</> option.
4382     In the expanded syntax,
4383     white-space characters in the RE are ignored, as are
4384     all characters between a <literal>#</>
4385     and the following newline (or the end of the RE).  This
4386     permits paragraphing and commenting a complex RE.
4387     There are three exceptions to that basic rule:
4388
4389     <itemizedlist>
4390      <listitem>
4391       <para>
4392        a white-space character or <literal>#</> preceded by <literal>\</> is
4393        retained
4394       </para>
4395      </listitem>
4396      <listitem>
4397       <para>
4398        white space or <literal>#</> within a bracket expression is retained
4399       </para>
4400      </listitem>
4401      <listitem>
4402       <para>
4403        white space and comments cannot appear within multicharacter symbols,
4404        such as <literal>(?:</>
4405       </para>
4406      </listitem>
4407     </itemizedlist>
4408
4409     For this purpose, white-space characters are blank, tab, newline, and
4410     any character that belongs to the <replaceable>space</> character class.
4411    </para>
4412
4413    <para>
4414     Finally, in an ARE, outside bracket expressions, the sequence
4415     <literal>(?#</><replaceable>ttt</><literal>)</>
4416     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4417     is a comment, completely ignored.
4418     Again, this is not allowed between the characters of
4419     multicharacter symbols, like <literal>(?:</>.
4420     Such comments are more a historical artifact than a useful facility,
4421     and their use is deprecated; use the expanded syntax instead.
4422    </para>
4423
4424    <para>
4425     <emphasis>None</> of these metasyntax extensions is available if
4426     an initial <literal>***=</> director
4427     has specified that the user's input be treated as a literal string
4428     rather than as an RE.
4429    </para>
4430    </sect3>
4431
4432    <sect3 id="posix-matching-rules">
4433     <title>Regular Expression Matching Rules</title>
4434
4435    <para>
4436     In the event that an RE could match more than one substring of a given
4437     string, the RE matches the one starting earliest in the string.
4438     If the RE could match more than one substring starting at that point,
4439     either the longest possible match or the shortest possible match will
4440     be taken, depending on whether the RE is <firstterm>greedy</> or
4441     <firstterm>non-greedy</>.
4442    </para>
4443
4444    <para>
4445     Whether an RE is greedy or not is determined by the following rules:
4446     <itemizedlist>
4447      <listitem>
4448       <para>
4449        Most atoms, and all constraints, have no greediness attribute (because
4450        they cannot match variable amounts of text anyway).
4451       </para>
4452      </listitem>
4453      <listitem>
4454       <para>
4455        Adding parentheses around an RE does not change its greediness.
4456       </para>
4457      </listitem>
4458      <listitem>
4459       <para>
4460        A quantified atom with a fixed-repetition quantifier
4461        (<literal>{</><replaceable>m</><literal>}</>
4462        or
4463        <literal>{</><replaceable>m</><literal>}?</>)
4464        has the same greediness (possibly none) as the atom itself.
4465       </para>
4466      </listitem>
4467      <listitem>
4468       <para>
4469        A quantified atom with other normal quantifiers (including
4470        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4471        with <replaceable>m</> equal to <replaceable>n</>)
4472        is greedy (prefers longest match).
4473       </para>
4474      </listitem>
4475      <listitem>
4476       <para>
4477        A quantified atom with a non-greedy quantifier (including
4478        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4479        with <replaceable>m</> equal to <replaceable>n</>)
4480        is non-greedy (prefers shortest match).
4481       </para>
4482      </listitem>
4483      <listitem>
4484       <para>
4485        A branch &mdash; that is, an RE that has no top-level
4486        <literal>|</> operator &mdash; has the same greediness as the first
4487        quantified atom in it that has a greediness attribute.
4488       </para>
4489      </listitem>
4490      <listitem>
4491       <para>
4492        An RE consisting of two or more branches connected by the
4493        <literal>|</> operator is always greedy.
4494       </para>
4495      </listitem>
4496     </itemizedlist>
4497    </para>
4498
4499    <para>
4500     The above rules associate greediness attributes not only with individual
4501     quantified atoms, but with branches and entire REs that contain quantified
4502     atoms.  What that means is that the matching is done in such a way that
4503     the branch, or whole RE, matches the longest or shortest possible
4504     substring <emphasis>as a whole</>.  Once the length of the entire match
4505     is determined, the part of it that matches any particular subexpression
4506     is determined on the basis of the greediness attribute of that
4507     subexpression, with subexpressions starting earlier in the RE taking
4508     priority over ones starting later.
4509    </para>
4510
4511    <para>
4512     An example of what this means:
4513 <screen>
4514 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4515 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4516 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4517 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4518 </screen>
4519     In the first case, the RE as a whole is greedy because <literal>Y*</>
4520     is greedy.  It can match beginning at the <literal>Y</>, and it matches
4521     the longest possible string starting there, i.e., <literal>Y123</>.
4522     The output is the parenthesized part of that, or <literal>123</>.
4523     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4524     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
4525     the shortest possible string starting there, i.e., <literal>Y1</>.
4526     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4527     the decision as to the overall match length; so it is forced to match
4528     just <literal>1</>.
4529    </para>
4530
4531    <para>
4532     In short, when an RE contains both greedy and non-greedy subexpressions,
4533     the total match length is either as long as possible or as short as
4534     possible, according to the attribute assigned to the whole RE.  The
4535     attributes assigned to the subexpressions only affect how much of that
4536     match they are allowed to <quote>eat</> relative to each other.
4537    </para>
4538
4539    <para>
4540     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4541     can be used to force greediness or non-greediness, respectively,
4542     on a subexpression or a whole RE.
4543    </para>
4544
4545    <para>
4546     Match lengths are measured in characters, not collating elements.
4547     An empty string is considered longer than no match at all.
4548     For example:
4549     <literal>bb*</>
4550     matches the three middle characters of <literal>abbbc</>;
4551     <literal>(week|wee)(night|knights)</>
4552     matches all ten characters of <literal>weeknights</>;
4553     when <literal>(.*).*</>
4554     is matched against <literal>abc</> the parenthesized subexpression
4555     matches all three characters; and when
4556     <literal>(a*)*</> is matched against <literal>bc</>
4557     both the whole RE and the parenthesized
4558     subexpression match an empty string.
4559    </para>
4560
4561    <para>
4562     If case-independent matching is specified,
4563     the effect is much as if all case distinctions had vanished from the
4564     alphabet.
4565     When an alphabetic that exists in multiple cases appears as an
4566     ordinary character outside a bracket expression, it is effectively
4567     transformed into a bracket expression containing both cases,
4568     e.g. <literal>x</> becomes <literal>[xX]</>.
4569     When it appears inside a bracket expression, all case counterparts
4570     of it are added to the bracket expression, e.g.
4571     <literal>[x]</> becomes <literal>[xX]</>
4572     and <literal>[^x]</> becomes <literal>[^xX]</>.
4573    </para>
4574
4575    <para>
4576     If newline-sensitive matching is specified, <literal>.</>
4577     and bracket expressions using <literal>^</>
4578     will never match the newline character
4579     (so that matches will never cross newlines unless the RE
4580     explicitly arranges it)
4581     and <literal>^</>and <literal>$</>
4582     will match the empty string after and before a newline
4583     respectively, in addition to matching at beginning and end of string
4584     respectively.
4585     But the ARE escapes <literal>\A</> and <literal>\Z</>
4586     continue to match beginning or end of string <emphasis>only</>.
4587    </para>
4588
4589    <para>
4590     If partial newline-sensitive matching is specified,
4591     this affects <literal>.</> and bracket expressions
4592     as with newline-sensitive matching, but not <literal>^</>
4593     and <literal>$</>.
4594    </para>
4595
4596    <para>
4597     If inverse partial newline-sensitive matching is specified,
4598     this affects <literal>^</> and <literal>$</>
4599     as with newline-sensitive matching, but not <literal>.</>
4600     and bracket expressions.
4601     This isn't very useful but is provided for symmetry.
4602    </para>
4603    </sect3>
4604
4605    <sect3 id="posix-limits-compatibility">
4606     <title>Limits and Compatibility</title>
4607
4608    <para>
4609     No particular limit is imposed on the length of REs in this
4610     implementation.  However,
4611     programs intended to be highly portable should not employ REs longer
4612     than 256 bytes,
4613     as a POSIX-compliant implementation can refuse to accept such REs.
4614    </para>
4615
4616    <para>
4617     The only feature of AREs that is actually incompatible with
4618     POSIX EREs is that <literal>\</> does not lose its special
4619     significance inside bracket expressions.
4620     All other ARE features use syntax which is illegal or has
4621     undefined or unspecified effects in POSIX EREs;
4622     the <literal>***</> syntax of directors likewise is outside the POSIX
4623     syntax for both BREs and EREs.
4624    </para>
4625
4626    <para>
4627     Many of the ARE extensions are borrowed from Perl, but some have
4628     been changed to clean them up, and a few Perl extensions are not present.
4629     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
4630     the lack of special treatment for a trailing newline,
4631     the addition of complemented bracket expressions to the things
4632     affected by newline-sensitive matching,
4633     the restrictions on parentheses and back references in lookahead
4634     constraints, and the longest/shortest-match (rather than first-match)
4635     matching semantics.
4636    </para>
4637
4638    <para>
4639     Two significant incompatibilities exist between AREs and the ERE syntax
4640     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
4641
4642     <itemizedlist>
4643      <listitem>
4644       <para>
4645        In AREs, <literal>\</> followed by an alphanumeric character is either
4646        an escape or an error, while in previous releases, it was just another
4647        way of writing the alphanumeric.
4648        This should not be much of a problem because there was no reason to
4649        write such a sequence in earlier releases.
4650       </para>
4651      </listitem>
4652      <listitem>
4653       <para>
4654        In AREs, <literal>\</> remains a special character within
4655        <literal>[]</>, so a literal <literal>\</> within a bracket
4656        expression must be written <literal>\\</>.
4657       </para>
4658      </listitem>
4659     </itemizedlist>
4660
4661     While these differences are unlikely to create a problem for most
4662     applications, you can avoid them if necessary by
4663     setting <varname>regex_flavor</> to <literal>extended</>.
4664    </para>
4665    </sect3>
4666
4667    <sect3 id="posix-basic-regexes">
4668     <title>Basic Regular Expressions</title>
4669
4670    <para>
4671     BREs differ from EREs in several respects.
4672     <literal>|</>, <literal>+</>, and <literal>?</>
4673     are ordinary characters and there is no equivalent
4674     for their functionality.
4675     The delimiters for bounds are
4676     <literal>\{</> and <literal>\}</>,
4677     with <literal>{</> and <literal>}</>
4678     by themselves ordinary characters.
4679     The parentheses for nested subexpressions are
4680     <literal>\(</> and <literal>\)</>,
4681     with <literal>(</> and <literal>)</> by themselves ordinary characters.
4682     <literal>^</> is an ordinary character except at the beginning of the
4683     RE or the beginning of a parenthesized subexpression,
4684     <literal>$</> is an ordinary character except at the end of the
4685     RE or the end of a parenthesized subexpression,
4686     and <literal>*</> is an ordinary character if it appears at the beginning
4687     of the RE or the beginning of a parenthesized subexpression
4688     (after a possible leading <literal>^</>).
4689     Finally, single-digit back references are available, and
4690     <literal>\&lt;</> and <literal>\&gt;</>
4691     are synonyms for
4692     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
4693     respectively; no other escapes are available.
4694    </para>
4695    </sect3>
4696
4697 <!-- end re_syntax.n man page -->
4698
4699   </sect2>
4700  </sect1>
4701
4702
4703   <sect1 id="functions-formatting">
4704    <title>Data Type Formatting Functions</title>
4705
4706    <indexterm>
4707     <primary>formatting</primary>
4708    </indexterm>
4709
4710    <indexterm>
4711     <primary>to_char</primary>
4712    </indexterm>
4713    <indexterm>
4714     <primary>to_date</primary>
4715    </indexterm>
4716    <indexterm>
4717     <primary>to_number</primary>
4718    </indexterm>
4719    <indexterm>
4720     <primary>to_timestamp</primary>
4721    </indexterm>
4722
4723    <para>
4724     The <productname>PostgreSQL</productname> formatting functions
4725     provide a powerful set of tools for converting various data types
4726     (date/time, integer, floating point, numeric) to formatted strings
4727     and for converting from formatted strings to specific data types.
4728     <xref linkend="functions-formatting-table"> lists them.
4729     These functions all follow a common calling convention: the first
4730     argument is the value to be formatted and the second argument is a
4731     template that defines the output or input format.
4732    </para>
4733    <para>
4734     The <function>to_timestamp</function> function can also take a single 
4735     <type>double precision</type> argument to convert from Unix epoch to 
4736     <type>timestamp with time zone</type>.
4737     (<type>Integer</type> Unix epochs are implicitly cast to 
4738     <type>double precision</type>.)
4739    </para>
4740
4741     <table id="functions-formatting-table">
4742      <title>Formatting Functions</title>
4743      <tgroup cols="4">
4744       <thead>
4745        <row>
4746         <entry>Function</entry>
4747         <entry>Return Type</entry>
4748         <entry>Description</entry>
4749         <entry>Example</entry>
4750        </row>
4751       </thead>
4752       <tbody>
4753        <row>
4754         <entry><literal><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</literal></entry>
4755         <entry><type>text</type></entry>
4756         <entry>convert time stamp to string</entry>
4757         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
4758        </row>
4759        <row>
4760         <entry><literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal></entry>
4761         <entry><type>text</type></entry>
4762         <entry>convert interval to string</entry>
4763         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
4764        </row>
4765        <row>
4766         <entry><literal><function>to_char</function>(<type>int</type>, <type>text</type>)</literal></entry>
4767         <entry><type>text</type></entry>
4768         <entry>convert integer to string</entry>
4769         <entry><literal>to_char(125, '999')</literal></entry>
4770        </row>
4771        <row>
4772         <entry><literal><function>to_char</function>(<type>double precision</type>,
4773         <type>text</type>)</literal></entry>
4774         <entry><type>text</type></entry>
4775         <entry>convert real/double precision to string</entry>
4776         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
4777        </row>
4778        <row>
4779         <entry><literal><function>to_char</function>(<type>numeric</type>, <type>text</type>)</literal></entry>
4780         <entry><type>text</type></entry>
4781         <entry>convert numeric to string</entry>
4782         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
4783        </row>
4784        <row>
4785         <entry><literal><function>to_date</function>(<type>text</type>, <type>text</type>)</literal></entry>
4786         <entry><type>date</type></entry>
4787         <entry>convert string to date</entry>
4788         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4789        </row>
4790        <row>
4791         <entry><literal><function>to_number</function>(<type>text</type>, <type>text</type>)</literal></entry>
4792         <entry><type>numeric</type></entry>
4793         <entry>convert string to numeric</entry>
4794         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
4795        </row>
4796        <row>
4797         <entry><literal><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</literal></entry>
4798         <entry><type>timestamp with time zone</type></entry>
4799         <entry>convert string to time stamp</entry>
4800         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4801        </row>
4802        <row>
4803         <entry><literal><function>to_timestamp</function>(<type>double precision</type>)</literal></entry>
4804         <entry><type>timestamp with time zone</type></entry>
4805         <entry>convert UNIX epoch to time stamp</entry>
4806         <entry><literal>to_timestamp(200120400)</literal></entry>
4807        </row>
4808       </tbody>
4809      </tgroup>
4810     </table>
4811
4812    <para>
4813     In an output template string (for <function>to_char</>), there are certain patterns that are
4814     recognized and replaced with appropriately-formatted data from the value
4815     to be formatted.  Any text that is not a template pattern is simply
4816     copied verbatim.  Similarly, in an input template string (for anything but <function>to_char</>), template patterns
4817     identify the parts of the input data string to be looked at and the
4818     values to be found there.
4819    </para>
4820
4821   <para>
4822    <xref linkend="functions-formatting-datetime-table"> shows the
4823    template patterns available for formatting date and time values.
4824   </para>
4825
4826     <table id="functions-formatting-datetime-table">
4827      <title>Template Patterns for Date/Time Formatting</title>
4828      <tgroup cols="2">
4829       <thead>
4830        <row>
4831         <entry>Pattern</entry>
4832         <entry>Description</entry>
4833        </row>
4834       </thead>
4835       <tbody>
4836        <row>
4837         <entry><literal>HH</literal></entry>
4838         <entry>hour of day (01-12)</entry>
4839        </row>
4840        <row>
4841         <entry><literal>HH12</literal></entry>
4842         <entry>hour of day (01-12)</entry>
4843        </row>       
4844        <row>
4845         <entry><literal>HH24</literal></entry>
4846         <entry>hour of day (00-23)</entry>
4847        </row>       
4848        <row>
4849         <entry><literal>MI</literal></entry>
4850         <entry>minute (00-59)</entry>
4851        </row>   
4852        <row>
4853         <entry><literal>SS</literal></entry>
4854         <entry>second (00-59)</entry>
4855        </row>
4856        <row>
4857         <entry><literal>MS</literal></entry>
4858         <entry>millisecond (000-999)</entry>
4859        </row>
4860        <row>
4861         <entry><literal>US</literal></entry>
4862         <entry>microsecond (000000-999999)</entry>
4863        </row>
4864        <row>
4865         <entry><literal>SSSS</literal></entry>
4866         <entry>seconds past midnight (0-86399)</entry>
4867        </row>
4868        <row>
4869         <entry><literal>AM</literal> or <literal>A.M.</literal> or
4870         <literal>PM</literal> or <literal>P.M.</literal></entry>
4871         <entry>meridian indicator (uppercase)</entry>
4872        </row>
4873        <row>
4874         <entry><literal>am</literal> or <literal>a.m.</literal> or
4875         <literal>pm</literal> or <literal>p.m.</literal></entry>
4876         <entry>meridian indicator (lowercase)</entry>
4877        </row>
4878        <row>
4879         <entry><literal>Y,YYY</literal></entry>
4880         <entry>year (4 and more digits) with comma</entry>
4881        </row>
4882        <row>
4883         <entry><literal>YYYY</literal></entry>
4884         <entry>year (4 and more digits)</entry>
4885        </row>
4886        <row>
4887         <entry><literal>YYY</literal></entry>
4888         <entry>last 3 digits of year</entry>
4889        </row>
4890        <row>
4891         <entry><literal>YY</literal></entry>
4892         <entry>last 2 digits of year</entry>
4893        </row>
4894        <row>
4895         <entry><literal>Y</literal></entry>
4896         <entry>last digit of year</entry>
4897        </row>
4898        <row>
4899         <entry><literal>IYYY</literal></entry>
4900         <entry>ISO year (4 and more digits)</entry>
4901        </row>
4902        <row>
4903         <entry><literal>IYY</literal></entry>
4904         <entry>last 3 digits of ISO year</entry>
4905        </row>
4906        <row>
4907         <entry><literal>IY</literal></entry>
4908         <entry>last 2 digits of ISO year</entry>
4909        </row>
4910        <row>
4911         <entry><literal>I</literal></entry>
4912         <entry>last digit of ISO year</entry>
4913        </row>
4914        <row>
4915         <entry><literal>BC</literal> or <literal>B.C.</literal> or
4916         <literal>AD</literal> or <literal>A.D.</literal></entry>
4917         <entry>era indicator (uppercase)</entry>
4918        </row>
4919        <row>
4920         <entry><literal>bc</literal> or <literal>b.c.</literal> or
4921         <literal>ad</literal> or <literal>a.d.</literal></entry>
4922         <entry>era indicator (lowercase)</entry>
4923        </row>
4924        <row>
4925         <entry><literal>MONTH</literal></entry>
4926         <entry>full uppercase month name (blank-padded to 9 chars)</entry>
4927        </row>
4928        <row>
4929         <entry><literal>Month</literal></entry>
4930         <entry>full mixed-case month name (blank-padded to 9 chars)</entry>
4931        </row>
4932        <row>
4933         <entry><literal>month</literal></entry>
4934         <entry>full lowercase month name (blank-padded to 9 chars)</entry>
4935        </row>
4936        <row>
4937         <entry><literal>MON</literal></entry>
4938         <entry>abbreviated uppercase month name (3 chars in English, localized lengths vary)</entry>
4939        </row>
4940        <row>
4941         <entry><literal>Mon</literal></entry>
4942         <entry>abbreviated mixed-case month name (3 chars in English, localized lengths vary)</entry>
4943        </row>
4944        <row>
4945         <entry><literal>mon</literal></entry>
4946         <entry>abbreviated lowercase month name (3 chars in English, localized lengths vary)</entry>
4947        </row>
4948        <row>
4949         <entry><literal>MM</literal></entry>
4950         <entry>month number (01-12)</entry>
4951        </row>
4952        <row>
4953         <entry><literal>DAY</literal></entry>
4954         <entry>full uppercase day name (blank-padded to 9 chars)</entry>
4955        </row>
4956        <row>
4957         <entry><literal>Day</literal></entry>
4958         <entry>full mixed-case day name (blank-padded to 9 chars)</entry>
4959        </row>
4960        <row>
4961         <entry><literal>day</literal></entry>
4962         <entry>full lowercase day name (blank-padded to 9 chars)</entry>
4963        </row>
4964        <row>
4965         <entry><literal>DY</literal></entry>
4966         <entry>abbreviated uppercase day name (3 chars in English, localized lengths vary)</entry>
4967        </row>
4968        <row>
4969         <entry><literal>Dy</literal></entry>
4970         <entry>abbreviated mixed-case day name (3 chars in English, localized lengths vary)</entry>
4971        </row>
4972        <row>
4973         <entry><literal>dy</literal></entry>
4974         <entry>abbreviated lowercase day name (3 chars in English, localized lengths vary)</entry>
4975        </row>
4976        <row>
4977         <entry><literal>DDD</literal></entry>
4978         <entry>day of year (001-366)</entry>
4979        </row>
4980        <row>
4981         <entry><literal>IDDD</literal></entry>
4982         <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
4983        </row>
4984        <row>
4985         <entry><literal>DD</literal></entry>
4986         <entry>day of month (01-31)</entry>
4987        </row>
4988        <row>
4989         <entry><literal>D</literal></entry>
4990         <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
4991        </row>
4992        <row>
4993         <entry><literal>ID</literal></entry>
4994         <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
4995        </row>
4996        <row>
4997         <entry><literal>W</literal></entry>
4998         <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
4999        </row> 
5000        <row>
5001         <entry><literal>WW</literal></entry>
5002         <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
5003        </row>
5004        <row>
5005         <entry><literal>IW</literal></entry>
5006         <entry>ISO week number of year (1 - 53; the first Thursday of the new year is in week 1.)</entry>
5007        </row>
5008        <row>
5009         <entry><literal>CC</literal></entry>
5010         <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
5011        </row>
5012        <row>
5013         <entry><literal>J</literal></entry>
5014         <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
5015        </row>
5016        <row>
5017         <entry><literal>Q</literal></entry>
5018         <entry>quarter</entry>
5019        </row>
5020        <row>
5021         <entry><literal>RM</literal></entry>
5022         <entry>month in Roman numerals (I-XII; I=January) (uppercase)</entry>
5023        </row>
5024        <row>
5025         <entry><literal>rm</literal></entry>
5026         <entry>month in Roman numerals (i-xii; i=January) (lowercase)</entry>
5027        </row>
5028        <row>
5029         <entry><literal>TZ</literal></entry>
5030         <entry>time-zone name (uppercase)</entry>
5031        </row>
5032        <row>
5033         <entry><literal>tz</literal></entry>
5034         <entry>time-zone name (lowercase)</entry>
5035        </row>
5036       </tbody>
5037      </tgroup>
5038     </table>
5039
5040    <para>
5041     Certain modifiers can be applied to any template pattern to alter its
5042     behavior.  For example, <literal>FMMonth</literal>
5043     is the <literal>Month</literal> pattern with the
5044     <literal>FM</literal> modifier.
5045     <xref linkend="functions-formatting-datetimemod-table"> shows the
5046     modifier patterns for date/time formatting.
5047    </para>
5048
5049     <table id="functions-formatting-datetimemod-table">
5050      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5051      <tgroup cols="3">
5052       <thead>
5053        <row>
5054         <entry>Modifier</entry>
5055         <entry>Description</entry>
5056         <entry>Example</entry>
5057        </row>
5058       </thead>
5059       <tbody>
5060        <row>
5061         <entry><literal>FM</literal> prefix</entry>
5062         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5063         <entry><literal>FMMonth</literal></entry>
5064        </row>
5065        <row>
5066         <entry><literal>TH</literal> suffix</entry>
5067         <entry>uppercase ordinal number suffix</entry>
5068         <entry><literal>DDTH</literal></entry>
5069        </row>   
5070        <row>
5071         <entry><literal>th</literal> suffix</entry>
5072         <entry>lowercase ordinal number suffix</entry>
5073         <entry><literal>DDth</literal></entry>
5074        </row>
5075        <row>
5076         <entry><literal>FX</literal> prefix</entry>
5077         <entry>fixed format global option (see usage notes)</entry>
5078         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5079        </row>   
5080        <row>
5081         <entry><literal>TM</literal> prefix</entry>
5082         <entry>translation mode (print localized day and month names based on
5083          <xref linkend="guc-lc-time">)</entry>
5084         <entry><literal>TMMonth</literal></entry>
5085        </row>       
5086        <row>
5087         <entry><literal>SP</literal> suffix</entry>
5088         <entry>spell mode (not yet implemented)</entry>
5089         <entry><literal>DDSP</literal></entry>
5090        </row>       
5091       </tbody>
5092      </tgroup>
5093     </table>
5094
5095    <para>
5096     Usage notes for date/time formatting:
5097
5098     <itemizedlist>
5099      <listitem>
5100       <para>
5101        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5102        that would otherwise be added to make the output of a pattern be
5103        fixed-width.
5104       </para>
5105      </listitem>
5106
5107      <listitem>
5108       <para>
5109        <literal>TM</literal> does not include trailing blanks.
5110       </para>
5111      </listitem>
5112
5113      <listitem>
5114       <para>
5115        <function>to_timestamp</function> and <function>to_date</function>
5116        skip multiple blank spaces in the input string if the <literal>FX</literal> option 
5117        is not used. <literal>FX</literal> must be specified as the first item
5118        in the template.  For example 
5119        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> is correct, but
5120        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error,
5121        because <function>to_timestamp</function> expects one space only.
5122       </para>
5123      </listitem>
5124
5125      <listitem>
5126       <para>
5127        Ordinary text is allowed in <function>to_char</function>
5128        templates and will be output literally.  You can put a substring
5129        in double quotes to force it to be interpreted as literal text
5130        even if it contains pattern key words.  For example, in
5131        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5132        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5133        will not be.
5134       </para>
5135      </listitem>
5136
5137      <listitem>
5138       <para>
5139        If you want to have a double quote in the output you must
5140        precede it with a backslash, for example <literal>E'\\"YYYY
5141        Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
5142        (Two backslashes are necessary because the backslash already
5143        has a special meaning when using the escape string syntax.)
5144       </para>
5145      </listitem>
5146
5147      <listitem>
5148       <para>
5149        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5150        <type>date</type> has a restriction if you use a year with more than 4 digits. You must
5151        use some non-digit character or template after <literal>YYYY</literal>,
5152        otherwise the year is always interpreted as 4 digits. For example
5153        (with the year 20000):
5154        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
5155        interpreted as a 4-digit year; instead use a non-digit 
5156        separator after the year, like
5157        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5158        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5159       </para>
5160      </listitem>
5161
5162      <listitem>
5163       <para>
5164        In conversions from string to <type>timestamp</type> or
5165        <type>date</type>, the <literal>CC</literal> field is ignored if there
5166        is a <literal>YYY</literal>, <literal>YYYY</literal> or
5167        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5168        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5169        as <literal>(CC-1)*100+YY</literal>.
5170       </para>
5171      </listitem>
5172
5173      <listitem>
5174       <para>
5175        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:
5176        <itemizedlist>
5177         <listitem>
5178          <para>
5179           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).
5180          </para>
5181         </listitem>
5182         <listitem>
5183          <para>
5184           Year and day of year, for example <literal>to_date('2006-291', 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5185          </para>
5186         </listitem>
5187        </itemizedlist>
5188       </para>
5189       <para>
5190        Attempting to construct a date using a mixture of ISO week and Gregorian date fields is nonsensical, and could yield unexpected results.  In the context of an ISO year, the concept of a 'month' or 'day of month' has no meaning.  In the context of a Gregorian year, the ISO week has no meaning.  Users should take care to keep Gregorian and ISO date specifications separate.
5191       </para>
5192      </listitem>
5193
5194      <listitem>
5195       <para>
5196        Millisecond (<literal>MS</literal>) and microsecond (<literal>US</literal>)
5197        values in a conversion from string to <type>timestamp</type> are used as part of the
5198        seconds after the decimal point. For example 
5199        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5200        but 300, because the conversion counts it as 12 + 0.3 seconds.
5201        This means for the format <literal>SS:MS</literal>, the input values
5202        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5203        same number of milliseconds. To get three milliseconds, one must use
5204        <literal>12:003</literal>, which the conversion counts as
5205        12 + 0.003 = 12.003 seconds.
5206       </para>
5207
5208       <para>
5209        Here is a more 
5210        complex example: 
5211        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5212        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5213        1230 microseconds = 2.021230 seconds. 
5214       </para>
5215      </listitem>
5216
5217      <listitem>
5218       <para>
5219         <function>to_char(..., 'ID')</function>'s day of the week numbering
5220         matches the <function>extract('isodow', ...)</function> function, but
5221         <function>to_char(..., 'D')</function>'s does not match
5222         <function>extract('dow', ...)</function>'s day numbering.
5223       </para>
5224      </listitem>
5225
5226      <listitem>
5227       <para><function>to_char(interval)</function> formats <literal>HH</> and 
5228         <literal>HH12</> as hours in a single day, while <literal>HH24</>
5229         can output hours exceeding a single day, e.g. &gt;24.
5230       </para>
5231      </listitem>
5232
5233     </itemizedlist>
5234    </para>
5235
5236   <para>
5237    <xref linkend="functions-formatting-numeric-table"> shows the
5238    template patterns available for formatting numeric values.
5239   </para>
5240
5241     <table id="functions-formatting-numeric-table">
5242      <title>Template Patterns for Numeric Formatting</title>
5243      <tgroup cols="2">
5244       <thead>
5245        <row>
5246         <entry>Pattern</entry>
5247         <entry>Description</entry>
5248        </row>
5249       </thead>
5250       <tbody>
5251        <row>
5252         <entry><literal>9</literal></entry>
5253         <entry>value with the specified number of digits</entry>
5254        </row>
5255        <row>
5256         <entry><literal>0</literal></entry>
5257         <entry>value with leading zeros</entry>
5258        </row>
5259        <row>
5260         <entry><literal>.</literal> (period)</entry>
5261         <entry>decimal point</entry>
5262        </row>       
5263        <row>
5264         <entry><literal>,</literal> (comma)</entry>
5265         <entry>group (thousand) separator</entry>
5266        </row>
5267        <row>
5268         <entry><literal>PR</literal></entry>
5269         <entry>negative value in angle brackets</entry>
5270        </row>
5271        <row>
5272         <entry><literal>S</literal></entry>
5273         <entry>sign anchored to number (uses locale)</entry>
5274        </row>
5275        <row>
5276         <entry><literal>L</literal></entry>
5277         <entry>currency symbol (uses locale)</entry>
5278        </row>
5279        <row>
5280         <entry><literal>D</literal></entry>
5281         <entry>decimal point (uses locale)</entry>
5282        </row>
5283        <row>
5284         <entry><literal>G</literal></entry>
5285         <entry>group separator (uses locale)</entry>
5286        </row>
5287        <row>
5288         <entry><literal>MI</literal></entry>
5289         <entry>minus sign in specified position (if number &lt; 0)</entry>
5290        </row>
5291        <row>
5292         <entry><literal>PL</literal></entry>
5293         <entry>plus sign in specified position (if number &gt; 0)</entry>
5294        </row>
5295        <row>
5296         <entry><literal>SG</literal></entry>
5297         <entry>plus/minus sign in specified position</entry>
5298        </row>
5299        <row>
5300         <entry><literal>RN</literal></entry>
5301         <entry>roman numeral (input between 1 and 3999)</entry>
5302        </row>
5303        <row>
5304         <entry><literal>TH</literal> or <literal>th</literal></entry>
5305         <entry>ordinal number suffix</entry>
5306        </row>
5307        <row>
5308         <entry><literal>V</literal></entry>
5309         <entry>shift specified number of digits (see notes)</entry>
5310        </row>
5311        <row>
5312         <entry><literal>EEEE</literal></entry>
5313         <entry>scientific notation (not implemented yet)</entry>
5314        </row>
5315       </tbody>
5316      </tgroup>
5317     </table>
5318
5319    <para>
5320     Usage notes for numeric formatting:
5321
5322     <itemizedlist>
5323      <listitem>
5324       <para>
5325        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5326        <literal>MI</literal> is not anchored to
5327        the number; for example,
5328        <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>,
5329        but <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>.
5330        The Oracle implementation does not allow the use of
5331        <literal>MI</literal> ahead of <literal>9</literal>, but rather
5332        requires that <literal>9</literal> precede
5333        <literal>MI</literal>.
5334       </para>
5335      </listitem>
5336
5337      <listitem>
5338       <para>
5339        <literal>9</literal> results in a value with the same number of 
5340        digits as there are <literal>9</literal>s. If a digit is
5341        not available it outputs a space.
5342       </para>
5343      </listitem>
5344
5345      <listitem>
5346       <para>
5347        <literal>TH</literal> does not convert values less than zero
5348        and does not convert fractional numbers.
5349       </para>
5350      </listitem>
5351
5352      <listitem>
5353       <para>
5354        <literal>PL</literal>, <literal>SG</literal>, and
5355        <literal>TH</literal> are <productname>PostgreSQL</productname>
5356        extensions. 
5357       </para>
5358      </listitem>
5359
5360      <listitem>
5361       <para>
5362        <literal>V</literal> effectively
5363        multiplies the input values by
5364        <literal>10^<replaceable>n</replaceable></literal>, where
5365        <replaceable>n</replaceable> is the number of digits following
5366        <literal>V</literal>. 
5367        <function>to_char</function> does not support the use of
5368        <literal>V</literal> combined with a decimal point.
5369        (E.g., <literal>99.9V99</literal> is not allowed.)
5370       </para>
5371      </listitem>
5372     </itemizedlist>
5373    </para>   
5374
5375    <para>
5376     Certain modifiers can be applied to any template pattern to alter its
5377     behavior.  For example, <literal>FM9999</literal>
5378     is the <literal>9999</literal> pattern with the
5379     <literal>FM</literal> modifier.
5380     <xref linkend="functions-formatting-numericmod-table"> shows the
5381     modifier patterns for numeric formatting.
5382    </para>
5383
5384     <table id="functions-formatting-numericmod-table">
5385      <title>Template Pattern Modifiers for Numeric Formatting</title>
5386      <tgroup cols="3">
5387       <thead>
5388        <row>
5389         <entry>Modifier</entry>
5390         <entry>Description</entry>
5391         <entry>Example</entry>
5392        </row>
5393       </thead>
5394       <tbody>
5395        <row>
5396         <entry><literal>FM</literal> prefix</entry>
5397         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5398         <entry><literal>FM9999</literal></entry>
5399        </row>
5400        <row>
5401         <entry><literal>TH</literal> suffix</entry>
5402         <entry>uppercase ordinal number suffix</entry>
5403         <entry><literal>999TH</literal></entry>
5404        </row>   
5405        <row>
5406         <entry><literal>th</literal> suffix</entry>
5407         <entry>lowercase ordinal number suffix</entry>
5408         <entry><literal>999th</literal></entry>
5409        </row>
5410       </tbody>
5411      </tgroup>
5412     </table>
5413
5414   <para>
5415    <xref linkend="functions-formatting-examples-table"> shows some
5416    examples of the use of the <function>to_char</function> function.
5417   </para>
5418
5419     <table id="functions-formatting-examples-table">
5420      <title><function>to_char</function> Examples</title>
5421      <tgroup cols="2">
5422       <thead>
5423        <row>
5424         <entry>Expression</entry>
5425         <entry>Result</entry>
5426        </row>
5427       </thead>
5428       <tbody>
5429        <row>
5430         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5431         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
5432        </row>
5433        <row>
5434         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5435         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
5436        </row>          
5437        <row>
5438         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5439         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
5440        </row>
5441        <row>
5442         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5443         <entry><literal>'-.1'</literal></entry>
5444        </row>
5445        <row>
5446         <entry><literal>to_char(0.1, '0.9')</literal></entry>
5447         <entry><literal>'&nbsp;0.1'</literal></entry>
5448        </row>
5449        <row>
5450         <entry><literal>to_char(12, '9990999.9')</literal></entry>
5451         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
5452        </row>
5453        <row>
5454         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5455         <entry><literal>'0012.'</literal></entry>
5456        </row>
5457        <row>
5458         <entry><literal>to_char(485, '999')</literal></entry>
5459         <entry><literal>'&nbsp;485'</literal></entry>
5460        </row>
5461        <row>
5462         <entry><literal>to_char(-485, '999')</literal></entry>
5463         <entry><literal>'-485'</literal></entry>
5464        </row>
5465        <row>
5466         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
5467         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
5468        </row>
5469        <row>
5470         <entry><literal>to_char(1485, '9,999')</literal></entry>
5471         <entry><literal>'&nbsp;1,485'</literal></entry>
5472        </row>
5473        <row>
5474         <entry><literal>to_char(1485, '9G999')</literal></entry>
5475         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
5476        </row>
5477        <row>
5478         <entry><literal>to_char(148.5, '999.999')</literal></entry>
5479         <entry><literal>'&nbsp;148.500'</literal></entry>
5480        </row>
5481        <row>
5482         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5483         <entry><literal>'148.5'</literal></entry>
5484        </row>
5485        <row>
5486         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5487         <entry><literal>'148.500'</literal></entry>
5488        </row>
5489        <row>
5490         <entry><literal>to_char(148.5, '999D999')</literal></entry>
5491         <entry><literal>'&nbsp;148,500'</literal></entry>        
5492        </row>
5493        <row>
5494         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5495         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
5496        </row>
5497        <row>
5498         <entry><literal>to_char(-485, '999S')</literal></entry>
5499         <entry><literal>'485-'</literal></entry>
5500        </row>
5501        <row>            
5502         <entry><literal>to_char(-485, '999MI')</literal></entry>
5503         <entry><literal>'485-'</literal></entry>        
5504        </row>
5505        <row>
5506         <entry><literal>to_char(485, '999MI')</literal></entry>
5507         <entry><literal>'485&nbsp;'</literal></entry>           
5508        </row>
5509        <row>
5510         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5511         <entry><literal>'485'</literal></entry>         
5512        </row>
5513        <row>
5514         <entry><literal>to_char(485, 'PL999')</literal></entry>
5515         <entry><literal>'+485'</literal></entry>        
5516        </row>
5517        <row>            
5518         <entry><literal>to_char(485, 'SG999')</literal></entry>
5519         <entry><literal>'+485'</literal></entry>        
5520        </row>
5521        <row>
5522         <entry><literal>to_char(-485, 'SG999')</literal></entry>
5523         <entry><literal>'-485'</literal></entry>        
5524        </row>
5525        <row>
5526         <entry><literal>to_char(-485, '9SG99')</literal></entry>
5527         <entry><literal>'4-85'</literal></entry>        
5528        </row>
5529        <row>
5530         <entry><literal>to_char(-485, '999PR')</literal></entry>
5531         <entry><literal>'&lt;485&gt;'</literal></entry>         
5532        </row>
5533        <row>
5534         <entry><literal>to_char(485, 'L999')</literal></entry>
5535         <entry><literal>'DM&nbsp;485</literal></entry>   
5536        </row>
5537        <row>
5538         <entry><literal>to_char(485, 'RN')</literal></entry>            
5539         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
5540        </row>
5541        <row>
5542         <entry><literal>to_char(485, 'FMRN')</literal></entry>  
5543         <entry><literal>'CDLXXXV'</literal></entry>
5544        </row>
5545        <row>
5546         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5547         <entry><literal>'V'</literal></entry>           
5548        </row>
5549        <row>
5550         <entry><literal>to_char(482, '999th')</literal></entry>
5551         <entry><literal>'&nbsp;482nd'</literal></entry>                         
5552        </row>
5553        <row>
5554         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
5555         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
5556        </row>
5557        <row>
5558         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
5559         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
5560        </row>
5561        <row>
5562         <entry><literal>to_char(12, '99V999')</literal></entry>         
5563         <entry><literal>'&nbsp;12000'</literal></entry>
5564        </row>
5565        <row>
5566         <entry><literal>to_char(12.4, '99V999')</literal></entry>
5567         <entry><literal>'&nbsp;12400'</literal></entry>
5568        </row>
5569        <row>            
5570         <entry><literal>to_char(12.45, '99V9')</literal></entry>
5571         <entry><literal>'&nbsp;125'</literal></entry>
5572        </row>
5573       </tbody>
5574      </tgroup>
5575     </table>
5576
5577   </sect1>
5578
5579
5580   <sect1 id="functions-datetime">
5581    <title>Date/Time Functions and Operators</title>
5582
5583   <para>
5584    <xref linkend="functions-datetime-table"> shows the available
5585    functions for date/time value processing, with details appearing in
5586    the following subsections.  <xref
5587    linkend="operators-datetime-table"> illustrates the behaviors of
5588    the basic arithmetic operators (<literal>+</literal>,
5589    <literal>*</literal>, etc.).  For formatting functions, refer to
5590    <xref linkend="functions-formatting">.  You should be familiar with
5591    the background information on date/time data types from <xref
5592    linkend="datatype-datetime">.
5593   </para>
5594
5595   <para>
5596    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
5597    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
5598    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
5599    For brevity, these variants are not shown separately.  Also, the
5600    <literal>+</> and <literal>*</> operators come in commutative pairs (for
5601    example both date + integer and integer + date); we show only one of each
5602    such pair.
5603   </para>
5604
5605     <table id="operators-datetime-table">
5606      <title>Date/Time Operators</title>
5607
5608      <tgroup cols="3">
5609       <thead>
5610        <row>
5611         <entry>Operator</entry>
5612         <entry>Example</entry>
5613         <entry>Result</entry>
5614        </row>
5615       </thead>
5616
5617       <tbody>
5618        <row>
5619         <entry> <literal>+</literal> </entry>
5620         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
5621         <entry><literal>date '2001-10-05'</literal></entry>
5622        </row>
5623
5624        <row>
5625         <entry> <literal>+</literal> </entry>
5626         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
5627         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
5628        </row>
5629
5630        <row>
5631         <entry> <literal>+</literal> </entry>
5632         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
5633         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
5634        </row>
5635
5636        <row>
5637         <entry> <literal>+</literal> </entry>
5638         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
5639         <entry><literal>interval '1 day 01:00:00'</literal></entry>
5640        </row>
5641
5642        <row>
5643         <entry> <literal>+</literal> </entry>
5644         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
5645         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
5646        </row>
5647
5648        <row>
5649         <entry> <literal>+</literal> </entry>
5650         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
5651         <entry><literal>time '04:00:00'</literal></entry>
5652        </row>
5653
5654        <row>
5655         <entry> <literal>-</literal> </entry>
5656         <entry><literal>- interval '23 hours'</literal></entry>
5657         <entry><literal>interval '-23:00:00'</literal></entry>
5658        </row>
5659
5660        <row>
5661         <entry> <literal>-</literal> </entry>
5662         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
5663         <entry><literal>integer '3'</literal></entry>
5664        </row>
5665
5666        <row>
5667         <entry> <literal>-</literal> </entry>
5668         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
5669         <entry><literal>date '2001-09-24'</literal></entry>
5670        </row>
5671
5672        <row>
5673         <entry> <literal>-</literal> </entry>
5674         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
5675         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
5676        </row>
5677
5678        <row>
5679         <entry> <literal>-</literal> </entry>
5680         <entry><literal>time '05:00' - time '03:00'</literal></entry>
5681         <entry><literal>interval '02:00:00'</literal></entry>
5682        </row>
5683
5684        <row>
5685         <entry> <literal>-</literal> </entry>
5686         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
5687         <entry><literal>time '03:00:00'</literal></entry>
5688        </row>
5689
5690        <row>
5691         <entry> <literal>-</literal> </entry>
5692         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
5693         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
5694        </row>
5695
5696        <row>
5697         <entry> <literal>-</literal> </entry>
5698         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
5699         <entry><literal>interval '1 day -01:00:00'</literal></entry>
5700        </row>
5701
5702        <row>
5703         <entry> <literal>-</literal> </entry>
5704         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
5705         <entry><literal>interval '1 day 15:00:00'</literal></entry>
5706        </row>
5707
5708        <row>
5709         <entry> <literal>*</literal> </entry>
5710         <entry><literal>900 * interval '1 second'</literal></entry>
5711         <entry><literal>interval '00:15:00'</literal></entry>
5712        </row>
5713
5714        <row>
5715         <entry> <literal>*</literal> </entry>
5716         <entry><literal>21 * interval '1 day'</literal></entry>
5717         <entry><literal>interval '21 days'</literal></entry>
5718        </row>
5719
5720        <row>
5721         <entry> <literal>*</literal> </entry>
5722         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
5723         <entry><literal>interval '03:30:00'</literal></entry>
5724        </row>
5725
5726        <row>
5727         <entry> <literal>/</literal> </entry>
5728         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
5729         <entry><literal>interval '00:40:00'</literal></entry>
5730        </row>
5731       </tbody>
5732      </tgroup>
5733     </table>
5734
5735    <indexterm>
5736     <primary>age</primary>
5737    </indexterm>
5738    <indexterm>
5739     <primary>clock_timestamp</primary>
5740    </indexterm>
5741    <indexterm>
5742     <primary>current_date</primary>
5743    </indexterm>
5744    <indexterm>
5745     <primary>current_time</primary>
5746    </indexterm>
5747    <indexterm>
5748     <primary>current_timestamp</primary>
5749    </indexterm>
5750    <indexterm>
5751     <primary>date_part</primary>
5752    </indexterm>
5753    <indexterm>
5754     <primary>date_trunc</primary>
5755    </indexterm>
5756    <indexterm>
5757     <primary>extract</primary>
5758    </indexterm>
5759    <indexterm>
5760     <primary>isfinite</primary>
5761    </indexterm>
5762    <indexterm>
5763     <primary>justify_days</primary>
5764    </indexterm>
5765    <indexterm>
5766     <primary>justify_hours</primary>
5767    </indexterm>
5768    <indexterm>
5769     <primary>justify_interval</primary>
5770    </indexterm>
5771    <indexterm>
5772     <primary>localtime</primary>
5773    </indexterm>
5774    <indexterm>
5775     <primary>localtimestamp</primary>
5776    </indexterm>
5777    <indexterm>
5778     <primary>now</primary>
5779    </indexterm>
5780    <indexterm>
5781     <primary>statement_timestamp</primary>
5782    </indexterm>
5783    <indexterm>
5784     <primary>timeofday</primary>
5785    </indexterm>
5786    <indexterm>
5787     <primary>transaction_timestamp</primary>
5788    </indexterm>
5789
5790     <table id="functions-datetime-table">
5791      <title>Date/Time Functions</title>
5792      <tgroup cols="5">
5793       <thead>
5794        <row>
5795         <entry>Function</entry>
5796         <entry>Return Type</entry>
5797         <entry>Description</entry>
5798         <entry>Example</entry>
5799         <entry>Result</entry>
5800        </row>
5801       </thead>
5802
5803       <tbody>
5804        <row>
5805         <entry><literal><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</literal></entry>
5806         <entry><type>interval</type></entry>
5807         <entry>Subtract arguments, producing a <quote>symbolic</> result that
5808         uses years and months</entry>
5809         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
5810         <entry><literal>43 years 9 mons 27 days</literal></entry>
5811        </row>
5812
5813        <row>
5814         <entry><literal><function>age</function>(<type>timestamp</type>)</literal></entry>
5815         <entry><type>interval</type></entry>
5816         <entry>Subtract from <function>current_date</function></entry>
5817         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
5818         <entry><literal>43 years 8 mons 3 days</literal></entry>
5819        </row>
5820
5821        <row>
5822         <entry><literal><function>clock_timestamp</function>()</literal></entry>
5823         <entry><type>timestamp with time zone</type></entry>
5824         <entry>Current date and time (changes during statement execution);
5825          see <xref linkend="functions-datetime-current">
5826         </entry>
5827         <entry></entry>
5828         <entry></entry>
5829        </row>
5830
5831        <row>
5832         <entry><literal><function>current_date</function></literal></entry>
5833         <entry><type>date</type></entry>
5834         <entry>Current date;
5835          see <xref linkend="functions-datetime-current">
5836         </entry>
5837         <entry></entry>
5838         <entry></entry>
5839        </row>
5840
5841        <row>
5842         <entry><literal><function>current_time</function></literal></entry>
5843         <entry><type>time with time zone</type></entry>
5844         <entry>Current time of day;
5845          see <xref linkend="functions-datetime-current">
5846         </entry>
5847         <entry></entry>
5848         <entry></entry>
5849        </row>
5850
5851        <row>
5852         <entry><literal><function>current_timestamp</function></literal></entry>
5853         <entry><type>timestamp with time zone</type></entry>
5854         <entry>Current date and time (start of current transaction);
5855          see <xref linkend="functions-datetime-current">
5856         </entry>
5857         <entry></entry>
5858         <entry></entry>
5859        </row>
5860
5861        <row>
5862         <entry><literal><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5863         <entry><type>double precision</type></entry>
5864         <entry>Get subfield (equivalent to <function>extract</function>);
5865          see <xref linkend="functions-datetime-extract">
5866         </entry>
5867         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5868         <entry><literal>20</literal></entry>
5869        </row>
5870
5871        <row>
5872         <entry><literal><function>date_part</function>(<type>text</type>, <type>interval</type>)</literal></entry>
5873         <entry><type>double precision</type></entry>
5874         <entry>Get subfield (equivalent to
5875          <function>extract</function>); see <xref linkend="functions-datetime-extract">
5876         </entry>
5877         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
5878         <entry><literal>3</literal></entry>
5879        </row>
5880
5881        <row>
5882         <entry><literal><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5883         <entry><type>timestamp</type></entry>
5884         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
5885         </entry>
5886         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5887         <entry><literal>2001-02-16 20:00:00</literal></entry>
5888        </row>
5889
5890        <row>
5891         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5892          <type>timestamp</type>)</literal></entry>
5893         <entry><type>double precision</type></entry>
5894         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5895         </entry>
5896         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
5897         <entry><literal>20</literal></entry>
5898        </row>
5899
5900        <row>
5901         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5902          <type>interval</type>)</literal></entry>
5903         <entry><type>double precision</type></entry>
5904         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5905         </entry>
5906         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
5907         <entry><literal>3</literal></entry>
5908        </row>
5909
5910        <row>
5911         <entry><literal><function>isfinite</function>(<type>timestamp</type>)</literal></entry>
5912         <entry><type>boolean</type></entry>
5913         <entry>Test for finite time stamp (not equal to infinity)</entry>
5914         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
5915         <entry><literal>true</literal></entry>
5916        </row>
5917
5918        <row>
5919         <entry><literal><function>isfinite</function>(<type>interval</type>)</literal></entry>
5920         <entry><type>boolean</type></entry>
5921         <entry>Test for finite interval</entry>
5922         <entry><literal>isfinite(interval '4 hours')</literal></entry>
5923         <entry><literal>true</literal></entry>
5924        </row>
5925
5926        <row>
5927         <entry><literal><function>justify_days</function>(<type>interval</type>)</literal></entry>
5928         <entry><type>interval</type></entry>
5929         <entry>Adjust interval so 30-day time periods are represented as months</entry>
5930         <entry><literal>justify_days(interval '30 days')</literal></entry>
5931         <entry><literal>1 month</literal></entry>
5932        </row>
5933
5934        <row>
5935         <entry><literal><function>justify_hours</function>(<type>interval</type>)</literal></entry>
5936         <entry><type>interval</type></entry>
5937         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
5938         <entry><literal>justify_hours(interval '24 hours')</literal></entry>
5939         <entry><literal>1 day</literal></entry>
5940        </row>
5941
5942        <row>
5943         <entry><literal><function>justify_interval</function>(<type>interval</type>)</literal></entry>
5944         <entry><type>interval</type></entry>
5945         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
5946         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
5947         <entry><literal>29 days 23:00:00</literal></entry>
5948        </row>
5949
5950        <row>
5951         <entry><literal><function>localtime</function></literal></entry>
5952         <entry><type>time</type></entry>
5953         <entry>Current time of day;
5954          see <xref linkend="functions-datetime-current">
5955         </entry>
5956         <entry></entry>
5957         <entry></entry>
5958        </row>
5959
5960        <row>
5961         <entry><literal><function>localtimestamp</function></literal></entry>
5962         <entry><type>timestamp</type></entry>
5963         <entry>Current date and time (start of current transaction);
5964          see <xref linkend="functions-datetime-current">
5965         </entry>
5966         <entry></entry>
5967         <entry></entry>
5968        </row>
5969
5970        <row>
5971         <entry><literal><function>now</function>()</literal></entry>
5972         <entry><type>timestamp with time zone</type></entry>
5973         <entry>Current date and time (start of current transaction);
5974          see <xref linkend="functions-datetime-current">
5975         </entry>
5976         <entry></entry>
5977         <entry></entry>
5978        </row>
5979
5980        <row>
5981         <entry><literal><function>statement_timestamp</function>()</literal></entry>
5982         <entry><type>timestamp with time zone</type></entry>
5983         <entry>Current date and time (start of current statement);
5984          see <xref linkend="functions-datetime-current">
5985         </entry>
5986         <entry></entry>
5987         <entry></entry>
5988        </row>
5989
5990        <row>
5991         <entry><literal><function>timeofday</function>()</literal></entry>
5992         <entry><type>text</type></entry>
5993         <entry>Current date and time
5994          (like <function>clock_timestamp</>, but as a <type>text</> string);
5995          see <xref linkend="functions-datetime-current">
5996         </entry>
5997         <entry></entry>
5998         <entry></entry>
5999        </row>
6000
6001        <row>
6002         <entry><literal><function>transaction_timestamp</function>()</literal></entry>
6003         <entry><type>timestamp with time zone</type></entry>
6004         <entry>Current date and time (start of current transaction);
6005          see <xref linkend="functions-datetime-current">
6006         </entry>
6007         <entry></entry>
6008         <entry></entry>
6009        </row>
6010       </tbody>
6011      </tgroup>
6012     </table>
6013
6014    <para>
6015     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6016     supported:
6017 <synopsis>
6018 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6019 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6020 </synopsis>
6021     This expression yields true when two time periods (defined by their
6022     endpoints) overlap, false when they do not overlap.  The endpoints
6023     can be specified as pairs of dates, times, or time stamps; or as
6024     a date, time, or time stamp followed by an interval.
6025    </para>
6026
6027 <screen>
6028 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6029        (DATE '2001-10-30', DATE '2002-10-30');
6030 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6031 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6032        (DATE '2001-10-30', DATE '2002-10-30');
6033 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6034 </screen>
6035
6036   <para>
6037    When adding an <type>interval</type> value to (or subtracting an 
6038    <type>interval</type> value from) a <type>timestamp with time zone</type> 
6039    value, the days component advances (or decrements) the date of the 
6040    <type>timestamp with time zone</type> by the indicated number of days. 
6041    Across daylight saving time changes (with the session time zone set to a 
6042    time zone that recognizes DST), this means <literal>interval '1 day'</literal> 
6043    does not necessarily equal <literal>interval '24 hours'</literal>. 
6044    For example, with the session time zone set to <literal>CST7CDT</literal>,
6045    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
6046    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>, 
6047    while adding <literal>interval '24 hours'</literal> to the same initial 
6048    <type>timestamp with time zone</type> produces
6049    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6050    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone 
6051    <literal>CST7CDT</literal>.
6052   </para>
6053
6054   <para>
6055    Note there can be ambiguity in the <literal>months</> returned by
6056    <function>age</> because different months have a different number of
6057    days.  <productname>PostgreSQL</>'s approach uses the month from the
6058    earlier of the two dates when calculating partial months.  For example,
6059    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6060    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6061    days</> because May has 31 days, while April has only 30.
6062   </para>
6063
6064   <sect2 id="functions-datetime-extract">
6065    <title><function>EXTRACT</function>, <function>date_part</function></title>
6066
6067    <indexterm>
6068     <primary>date_part</primary>
6069    </indexterm>
6070    <indexterm>
6071     <primary>extract</primary>
6072    </indexterm>
6073
6074 <synopsis>
6075 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6076 </synopsis>
6077
6078    <para>
6079     The <function>extract</function> function retrieves subfields
6080     such as year or hour from date/time values.
6081     <replaceable>source</replaceable> must be a value expression of
6082     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6083     (Expressions of type <type>date</type> will
6084     be cast to <type>timestamp</type> and can therefore be used as
6085     well.)  <replaceable>field</replaceable> is an identifier or
6086     string that selects what field to extract from the source value.
6087     The <function>extract</function> function returns values of type
6088     <type>double precision</type>.
6089     The following are valid field names:
6090
6091     <!-- alphabetical -->
6092     <variablelist>
6093      <varlistentry>
6094       <term><literal>century</literal></term>
6095       <listitem>
6096        <para>
6097         The century
6098        </para>
6099
6100 <screen>
6101 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6102 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6103 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6104 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6105 </screen>
6106
6107        <para>
6108         The first century starts at 0001-01-01 00:00:00 AD, although
6109         they did not know it at the time. This definition applies to all
6110         Gregorian calendar countries. There is no century number 0,
6111         you go from -1 to 1.
6112
6113         If you disagree with this, please write your complaint to:
6114         Pope, Cathedral Saint-Peter of Roma, Vatican.
6115        </para>
6116
6117        <para>
6118         <productname>PostgreSQL</productname> releases before 8.0 did not
6119         follow the conventional numbering of centuries, but just returned
6120         the year field divided by 100.
6121        </para>
6122       </listitem>
6123      </varlistentry>
6124
6125      <varlistentry>
6126       <term><literal>day</literal></term>
6127       <listitem>
6128        <para>
6129         The day (of the month) field (1 - 31)
6130        </para>
6131
6132 <screen>
6133 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6134 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6135 </screen>
6136       </listitem>
6137      </varlistentry>
6138
6139      <varlistentry>
6140       <term><literal>decade</literal></term>
6141       <listitem>
6142        <para>
6143         The year field divided by 10
6144        </para>
6145
6146 <screen>
6147 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6148 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6149 </screen>
6150       </listitem>
6151      </varlistentry>
6152
6153      <varlistentry>
6154       <term><literal>dow</literal></term>
6155       <listitem>
6156        <para>
6157         The day of the week as Sunday(<literal>0</>) to
6158         Saturday(<literal>6</>)
6159        </para>
6160
6161 <screen>
6162 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6163 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6164 </screen>
6165        <para>
6166         Note that <function>extract</function>'s day of the week numbering
6167         is different from that of the <function>to_char(...,
6168         'D')</function> function.
6169        </para>
6170
6171       </listitem>
6172      </varlistentry>
6173
6174      <varlistentry>
6175       <term><literal>doy</literal></term>
6176       <listitem>
6177        <para>
6178         The day of the year (1 - 365/366)
6179        </para>
6180
6181 <screen>
6182 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6183 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6184 </screen>
6185       </listitem>
6186      </varlistentry>
6187
6188      <varlistentry>
6189       <term><literal>epoch</literal></term>
6190       <listitem>
6191        <para>
6192         For <type>date</type> and <type>timestamp</type> values, the
6193         number of seconds since 1970-01-01 00:00:00-00 (can be negative);
6194         for <type>interval</type> values, the total number
6195         of seconds in the interval
6196        </para>
6197
6198 <screen>
6199 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-08');
6200 <lineannotation>Result: </lineannotation><computeroutput>982384720</computeroutput>
6201
6202 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6203 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6204 </screen>
6205
6206        <para>
6207         Here is how you can convert an epoch value back to a time
6208         stamp:
6209        </para>
6210
6211 <screen>
6212 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720 * INTERVAL '1 second';
6213 </screen>
6214       </listitem>
6215      </varlistentry>
6216
6217      <varlistentry>
6218       <term><literal>hour</literal></term>
6219       <listitem>
6220        <para>
6221         The hour field (0 - 23)
6222        </para>
6223
6224 <screen>
6225 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6226 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6227 </screen>
6228       </listitem>
6229      </varlistentry>
6230
6231      <varlistentry>
6232       <term><literal>isodow</literal></term>
6233       <listitem>
6234        <para>
6235         The day of the week as Monday(<literal>1</>) to
6236         Sunday(<literal>7</>)
6237        </para>
6238
6239 <screen>
6240 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6241 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6242 </screen>
6243        <para>
6244         This is identical to <literal>dow</> except for Sunday.  This
6245         matches the <acronym>ISO</> 8601 day of the week numbering.
6246        </para>
6247
6248       </listitem>
6249      </varlistentry>
6250
6251      <varlistentry>
6252       <term><literal>isoyear</literal></term>
6253       <listitem>
6254        <para>
6255         The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals).
6256        </para>
6257
6258 <screen>
6259 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6260 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6261 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6262 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6263 </screen>
6264
6265        <para>
6266         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.
6267        </para>
6268        <para>
6269         This field is not available in PostgreSQL releases prior to 8.3.
6270        </para>
6271       </listitem>
6272      </varlistentry>
6273
6274      <varlistentry>
6275       <term><literal>microseconds</literal></term>
6276       <listitem>
6277        <para>
6278         The seconds field, including fractional parts, multiplied by 1
6279         000 000.  Note that this includes full seconds.
6280        </para>
6281
6282 <screen>
6283 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6284 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6285 </screen>
6286       </listitem>
6287      </varlistentry>
6288
6289      <varlistentry>
6290       <term><literal>millennium</literal></term>
6291       <listitem>
6292        <para>
6293         The millennium
6294        </para>
6295
6296 <screen>
6297 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6298 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6299 </screen>
6300
6301        <para>
6302         Years in the 1900s are in the second millennium.
6303         The third millennium starts January 1, 2001.
6304        </para>
6305
6306        <para>
6307         <productname>PostgreSQL</productname> releases before 8.0 did not
6308         follow the conventional numbering of millennia, but just returned
6309         the year field divided by 1000.
6310        </para>
6311       </listitem>
6312      </varlistentry>
6313
6314      <varlistentry>
6315       <term><literal>milliseconds</literal></term>
6316       <listitem>
6317        <para>
6318         The seconds field, including fractional parts, multiplied by
6319         1000.  Note that this includes full seconds.
6320        </para>
6321
6322 <screen>
6323 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6324 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6325 </screen>
6326       </listitem>
6327      </varlistentry>
6328
6329      <varlistentry>
6330       <term><literal>minute</literal></term>
6331       <listitem>
6332        <para>
6333         The minutes field (0 - 59)
6334        </para>
6335
6336 <screen>
6337 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6338 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6339 </screen>
6340       </listitem>
6341      </varlistentry>
6342
6343      <varlistentry>
6344       <term><literal>month</literal></term>
6345       <listitem>
6346        <para>
6347         For <type>timestamp</type> values, the number of the month
6348         within the year (1 - 12) ; for <type>interval</type> values
6349         the number of months, modulo 12 (0 - 11)
6350        </para>
6351
6352 <screen>
6353 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6354 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6355
6356 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6357 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6358
6359 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6360 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6361 </screen>
6362       </listitem>
6363      </varlistentry>
6364
6365      <varlistentry>
6366       <term><literal>quarter</literal></term>
6367       <listitem>
6368        <para>
6369         The quarter of the year (1 - 4) that the day is in
6370        </para>
6371
6372 <screen>
6373 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6374 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6375 </screen>
6376       </listitem>
6377      </varlistentry>
6378
6379      <varlistentry>
6380       <term><literal>second</literal></term>
6381       <listitem>
6382        <para>
6383         The seconds field, including fractional parts (0 -
6384         59<footnote><simpara>60 if leap seconds are
6385         implemented by the operating system</simpara></footnote>)
6386        </para>
6387
6388 <screen>
6389 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6390 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6391
6392 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6393 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6394 </screen>
6395       </listitem>
6396      </varlistentry>
6397      <varlistentry>
6398       <term><literal>timezone</literal></term>
6399       <listitem>
6400        <para>
6401         The time zone offset from UTC, measured in seconds.  Positive values
6402         correspond to time zones east of UTC, negative values to
6403         zones west of UTC.
6404        </para>
6405       </listitem>
6406      </varlistentry>
6407
6408      <varlistentry>
6409       <term><literal>timezone_hour</literal></term>
6410       <listitem>
6411        <para>
6412         The hour component of the time zone offset
6413        </para>
6414       </listitem>
6415      </varlistentry>
6416
6417      <varlistentry>
6418       <term><literal>timezone_minute</literal></term>
6419       <listitem>
6420        <para>
6421         The minute component of the time zone offset
6422        </para>
6423       </listitem>
6424      </varlistentry>
6425
6426      <varlistentry>
6427       <term><literal>week</literal></term>
6428       <listitem>
6429        <para>
6430         The number of the week of the year that the day is in.  By definition
6431         (<acronym>ISO</acronym> 8601), the first week of a year
6432         contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
6433         week starts on Monday.)  In other words, the first Thursday of
6434         a year is in week 1 of that year.
6435        </para>
6436        <para>
6437         Because of this, it is possible for early January dates to be part of the 
6438         52nd or 53rd week of the previous year.  For example, <literal>2005-01-01</>
6439         is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of 
6440         the 52nd week of year 2005.
6441        </para>
6442
6443 <screen>
6444 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6445 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6446 </screen>
6447       </listitem>
6448      </varlistentry>
6449
6450      <varlistentry>
6451       <term><literal>year</literal></term>
6452       <listitem>
6453        <para>
6454         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting 
6455         <literal>BC</> years from <literal>AD</> years should be done with care.
6456        </para>
6457
6458 <screen>
6459 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6460 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6461 </screen>
6462       </listitem>
6463      </varlistentry>
6464
6465     </variablelist>
6466    </para>
6467
6468    <para>
6469     The <function>extract</function> function is primarily intended
6470     for computational processing.  For formatting date/time values for
6471     display, see <xref linkend="functions-formatting">.
6472    </para>
6473
6474    <para>
6475     The <function>date_part</function> function is modeled on the traditional
6476     <productname>Ingres</productname> equivalent to the
6477     <acronym>SQL</acronym>-standard function <function>extract</function>:
6478 <synopsis>
6479 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6480 </synopsis>
6481     Note that here the <replaceable>field</replaceable> parameter needs to
6482     be a string value, not a name.  The valid field names for
6483     <function>date_part</function> are the same as for
6484     <function>extract</function>.
6485    </para>
6486
6487 <screen>
6488 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
6489 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6490
6491 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
6492 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
6493 </screen>
6494
6495   </sect2>
6496
6497   <sect2 id="functions-datetime-trunc">
6498    <title><function>date_trunc</function></title>
6499
6500    <indexterm>
6501     <primary>date_trunc</primary>
6502    </indexterm>
6503
6504    <para>
6505     The function <function>date_trunc</function> is conceptually
6506     similar to the <function>trunc</function> function for numbers.
6507    </para>
6508
6509    <para>
6510 <synopsis>
6511 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6512 </synopsis>
6513     <replaceable>source</replaceable> is a value expression of type
6514     <type>timestamp</type> or <type>interval</>.
6515     (Values of type <type>date</type> and
6516     <type>time</type> are cast automatically, to <type>timestamp</type> or
6517     <type>interval</> respectively.)
6518     <replaceable>field</replaceable> selects to which precision to
6519     truncate the input value.  The return value is of type
6520     <type>timestamp</type> or <type>interval</>
6521     with all fields that are less significant than the
6522     selected one set to zero (or one, for day and month).
6523    </para>
6524
6525    <para>
6526     Valid values for <replaceable>field</replaceable> are:
6527     <simplelist>
6528      <member><literal>microseconds</literal></member>
6529      <member><literal>milliseconds</literal></member>
6530      <member><literal>second</literal></member>
6531      <member><literal>minute</literal></member>
6532      <member><literal>hour</literal></member>
6533      <member><literal>day</literal></member>
6534      <member><literal>week</literal></member>
6535      <member><literal>month</literal></member>
6536      <member><literal>quarter</literal></member>
6537      <member><literal>year</literal></member>
6538      <member><literal>decade</literal></member>
6539      <member><literal>century</literal></member>
6540      <member><literal>millennium</literal></member>
6541     </simplelist>
6542    </para>
6543
6544    <para>
6545     Examples:
6546 <screen>
6547 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
6548 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
6549
6550 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
6551 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
6552 </screen>
6553    </para>
6554   </sect2>
6555
6556   <sect2 id="functions-datetime-zoneconvert">
6557    <title><literal>AT TIME ZONE</literal></title>
6558
6559    <indexterm>
6560     <primary>time zone</primary>
6561     <secondary>conversion</secondary>
6562    </indexterm>
6563
6564    <indexterm>
6565     <primary>AT TIME ZONE</primary>
6566    </indexterm>
6567
6568    <para>
6569     The <literal>AT TIME ZONE</literal> construct allows conversions
6570     of time stamps to different time zones.  <xref
6571     linkend="functions-datetime-zoneconvert-table"> shows its
6572     variants.
6573    </para>
6574
6575     <table id="functions-datetime-zoneconvert-table">
6576      <title><literal>AT TIME ZONE</literal> Variants</title>
6577      <tgroup cols="3">
6578       <thead>
6579        <row>
6580         <entry>Expression</entry>
6581         <entry>Return Type</entry>
6582         <entry>Description</entry>
6583        </row>
6584       </thead>
6585
6586       <tbody>
6587        <row>
6588         <entry>
6589          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6590         </entry>
6591         <entry><type>timestamp with time zone</type></entry>
6592         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
6593        </row>
6594
6595        <row>
6596         <entry>
6597          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6598         </entry>
6599         <entry><type>timestamp without time zone</type></entry>
6600         <entry>Convert given time stamp <emphasis>with time zone</> to the new time zone</entry>
6601        </row>
6602
6603        <row>
6604         <entry>
6605          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6606         </entry>
6607         <entry><type>time with time zone</type></entry>
6608         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
6609        </row>
6610       </tbody>
6611      </tgroup>
6612     </table>
6613
6614    <para>
6615     In these expressions, the desired time zone <replaceable>zone</> can be
6616     specified either as a text string (e.g., <literal>'PST'</literal>)
6617     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
6618     In the text case, a time zone name can be specified in any of the ways
6619     described in <xref linkend="datatype-timezones">.
6620    </para>
6621
6622    <para>
6623     Examples (supposing that the local time zone is <literal>PST8PDT</>):
6624 <screen>
6625 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
6626 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
6627
6628 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
6629 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
6630 </screen>
6631     The first example takes a time stamp without time zone and interprets it as MST time
6632     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes 
6633     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
6634    </para>
6635
6636    <para>
6637     The function <literal><function>timezone</function>(<replaceable>zone</>,
6638     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
6639     <literal><replaceable>timestamp</> AT TIME ZONE
6640     <replaceable>zone</></literal>. 
6641    </para>
6642   </sect2>
6643
6644   <sect2 id="functions-datetime-current">
6645    <title>Current Date/Time</title>
6646
6647    <indexterm>
6648     <primary>date</primary>
6649     <secondary>current</secondary>
6650    </indexterm>
6651
6652    <indexterm>
6653     <primary>time</primary>
6654     <secondary>current</secondary>
6655    </indexterm>
6656
6657    <para>
6658     <productname>PostgreSQL</productname> provides a number of functions
6659     that return values related to the current date and time.  These
6660     SQL-standard functions all return values based on the start time of
6661     the current transaction:
6662 <synopsis>
6663 CURRENT_DATE
6664 CURRENT_TIME
6665 CURRENT_TIMESTAMP
6666 CURRENT_TIME(<replaceable>precision</replaceable>)
6667 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
6668 LOCALTIME
6669 LOCALTIMESTAMP
6670 LOCALTIME(<replaceable>precision</replaceable>)
6671 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
6672 </synopsis>
6673     </para>
6674
6675     <para>
6676      <function>CURRENT_TIME</function> and
6677      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
6678      <function>LOCALTIME</function> and
6679      <function>LOCALTIMESTAMP</function> deliver values without time zone.
6680     </para>
6681
6682     <para>
6683      <function>CURRENT_TIME</function>,
6684      <function>CURRENT_TIMESTAMP</function>,
6685      <function>LOCALTIME</function>, and
6686      <function>LOCALTIMESTAMP</function>
6687      can optionally be given
6688      a precision parameter, which causes the result to be rounded
6689      to that many fractional digits in the seconds field.  Without a precision parameter,
6690      the result is given to the full available precision.
6691     </para>
6692
6693    <para>
6694     Some examples:
6695 <screen>
6696 SELECT CURRENT_TIME;
6697 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
6698
6699 SELECT CURRENT_DATE;
6700 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
6701
6702 SELECT CURRENT_TIMESTAMP;
6703 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
6704
6705 SELECT CURRENT_TIMESTAMP(2);
6706 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
6707
6708 SELECT LOCALTIMESTAMP;
6709 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
6710 </screen>
6711    </para>
6712
6713    <para>
6714     Since these functions return
6715     the start time of the current transaction, their values do not
6716     change during the transaction. This is considered a feature:
6717     the intent is to allow a single transaction to have a consistent
6718     notion of the <quote>current</quote> time, so that multiple
6719     modifications within the same transaction bear the same
6720     time stamp.
6721    </para>
6722
6723    <note>
6724     <para>
6725      Other database systems might advance these values more
6726      frequently.
6727     </para>
6728    </note>
6729
6730    <para>
6731     <productname>PostgreSQL</productname> also provides functions that
6732     return the start time of the current statement, as well as the actual
6733     current time at the instant the function is called.  The complete list
6734     of non-SQL-standard time functions is:
6735 <synopsis>
6736 now()
6737 transaction_timestamp()
6738 statement_timestamp()
6739 clock_timestamp()
6740 timeofday()
6741 </synopsis>
6742    </para>
6743
6744    <para>
6745     <function>now()</> is a traditional <productname>PostgreSQL</productname>
6746     equivalent to <function>CURRENT_TIMESTAMP</function>.
6747     <function>transaction_timestamp()</> is likewise equivalent to
6748     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
6749     what it returns.
6750     <function>statement_timestamp()</> returns the start time of the current
6751     statement (more specifically, the time of receipt of the latest command
6752     message from the client).
6753     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
6754     return the same value during the first command of a transaction, but might
6755     differ during subsequent commands.
6756     <function>clock_timestamp()</> returns the actual current time, and
6757     therefore its value changes even within a single SQL command.
6758     <function>timeofday()</> is a historical
6759     <productname>PostgreSQL</productname> function.  Like
6760     <function>clock_timestamp()</>, it returns the actual current time,
6761     but as a formatted <type>text</> string rather than a <type>timestamp
6762     with time zone</> value.
6763    </para>
6764
6765    <para>
6766     All the date/time data types also accept the special literal value
6767     <literal>now</literal> to specify the current date and time (again,
6768     interpreted as the transaction start time).  Thus,
6769     the following three all return the same result:
6770 <programlisting>
6771 SELECT CURRENT_TIMESTAMP;
6772 SELECT now();
6773 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
6774 </programlisting>
6775    </para>
6776
6777     <tip>
6778      <para>
6779       You do not want to use the third form when specifying a <literal>DEFAULT</>
6780       clause while creating a table.  The system will convert <literal>now</literal>
6781       to a <type>timestamp</type> as soon as the constant is parsed, so that when
6782       the default value is needed,
6783       the time of the table creation would be used!  The first two
6784       forms will not be evaluated until the default value is used,
6785       because they are function calls.  Thus they will give the desired
6786       behavior of defaulting to the time of row insertion.
6787      </para>
6788     </tip>
6789   </sect2>
6790
6791   <sect2 id="functions-datetime-delay">
6792    <title>Delaying Execution</title>
6793
6794    <indexterm>
6795     <primary>pg_sleep</primary>
6796    </indexterm>
6797    <indexterm>
6798     <primary>sleep</primary>
6799    </indexterm>
6800    <indexterm>
6801     <primary>delay</primary>
6802    </indexterm>
6803
6804    <para>
6805     The following function is available to delay execution of the server
6806     process:
6807 <synopsis>
6808 pg_sleep(<replaceable>seconds</replaceable>)
6809 </synopsis>
6810
6811     <function>pg_sleep</function> makes the current session's process
6812     sleep until <replaceable>seconds</replaceable> seconds have
6813     elapsed.  <replaceable>seconds</replaceable> is a value of type
6814     <type>double precision</>, so fractional-second delays can be specified.
6815     For example:
6816
6817 <programlisting>
6818 SELECT pg_sleep(1.5);
6819 </programlisting>
6820    </para>
6821
6822    <note>
6823      <para>
6824       The effective resolution of the sleep interval is platform-specific;
6825       0.01 seconds is a common value.  The sleep delay will be at least as long
6826       as specified. It might be longer depending on factors such as server load.
6827      </para>
6828    </note>
6829
6830    <warning>
6831      <para>
6832       Make sure that your session does not hold more locks than necessary
6833       when calling <function>pg_sleep</function>.  Otherwise other sessions
6834       might have to wait for your sleeping process, slowing down the entire
6835       system.
6836      </para>
6837    </warning>
6838   </sect2>
6839
6840  </sect1>
6841
6842   
6843  <sect1 id="functions-enum">
6844   <title>Enum Support Functions</title>
6845
6846   <para>
6847    For enum types (described in <xref linkend="datatype-enum">),
6848    there are several functions that allow cleaner programming without
6849    hard-coding particular values of an enum type.
6850    These are listed in <xref linkend="functions-enum-table">. The examples
6851    assume an enum type created as:
6852
6853 <programlisting>
6854 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
6855 </programlisting>
6856
6857   </para>
6858
6859   <table id="functions-enum-table">
6860     <title>Enum Support Functions</title>
6861     <tgroup cols="4">
6862      <thead>
6863       <row>
6864        <entry>Function</entry>
6865        <entry>Description</entry>
6866        <entry>Example</entry>
6867        <entry>Example Result</entry>
6868       </row>
6869      </thead>
6870      <tbody>
6871       <row>
6872        <entry><literal>enum_first(anyenum)</literal></entry>
6873        <entry>Returns the first value of the input enum type</entry>
6874        <entry><literal>enum_first(null::rainbow)</literal></entry>
6875        <entry><literal>red</literal></entry>
6876       </row>
6877       <row>
6878        <entry><literal>enum_last(anyenum)</literal></entry>
6879        <entry>Returns the last value of the input enum type</entry>
6880        <entry><literal>enum_last(null::rainbow)</literal></entry>
6881        <entry><literal>purple</literal></entry>
6882       </row>
6883       <row>
6884        <entry><literal>enum_range(anyenum)</literal></entry>
6885        <entry>Returns all values of the input enum type in an ordered array</entry>
6886        <entry><literal>enum_range(null::rainbow)</literal></entry>
6887        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
6888       </row>
6889       <row>
6890        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
6891        <entry morerows="2">
6892         Returns the range between the two given enum values, as an ordered
6893         array. The values must be from the same enum type. If the first
6894         parameter is null, the result will start with the first value of
6895         the enum type.
6896         If the second parameter is null, the result will end with the last
6897         value of the enum type.
6898        </entry>
6899        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
6900        <entry><literal>{orange,yellow,green}</literal></entry>
6901       </row>
6902       <row>
6903        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
6904        <entry><literal>{red,orange,yellow,green}</literal></entry>
6905       </row>
6906       <row>
6907        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
6908        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
6909       </row>
6910      </tbody>
6911     </tgroup>
6912    </table>
6913
6914    <para>
6915     Notice that except for the two-argument form of <function>enum_range</>,
6916     these functions disregard the specific value passed to them; they care
6917     only about its declared data type.  Either null or a specific value of
6918     the type can be passed, with the same result.  It is more common to
6919     apply these functions to a table column or function argument than to
6920     a hardwired type name as suggested by the examples.
6921    </para>
6922  </sect1>
6923
6924  <sect1 id="functions-geometry">
6925   <title>Geometric Functions and Operators</title>
6926
6927    <para>
6928     The geometric types <type>point</type>, <type>box</type>,
6929     <type>lseg</type>, <type>line</type>, <type>path</type>,
6930     <type>polygon</type>, and <type>circle</type> have a large set of
6931     native support functions and operators, shown in <xref
6932     linkend="functions-geometry-op-table">, <xref
6933     linkend="functions-geometry-func-table">, and <xref
6934     linkend="functions-geometry-conv-table">.
6935    </para>
6936
6937    <caution>
6938     <para>
6939      Note that the <quote>same as</> operator, <literal>~=</>, represents
6940      the usual notion of equality for the <type>point</type>,
6941      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
6942      Some of these types also have an <literal>=</> operator, but
6943      <literal>=</> compares
6944      for equal <emphasis>areas</> only.  The other scalar comparison operators
6945      (<literal>&lt;=</> and so on) likewise compare areas for these types.
6946     </para>
6947    </caution>
6948
6949    <table id="functions-geometry-op-table">
6950      <title>Geometric Operators</title>
6951      <tgroup cols="3">
6952       <thead>
6953        <row>
6954         <entry>Operator</entry>
6955         <entry>Description</entry>
6956         <entry>Example</entry>
6957        </row>
6958       </thead>
6959       <tbody>
6960        <row>
6961         <entry> <literal>+</literal> </entry>
6962         <entry>Translation</entry>
6963         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
6964        </row>
6965        <row>
6966         <entry> <literal>-</literal> </entry>
6967         <entry>Translation</entry>
6968         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
6969        </row>
6970        <row>
6971         <entry> <literal>*</literal> </entry>
6972         <entry>Scaling/rotation</entry>
6973         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
6974        </row>
6975        <row>
6976         <entry> <literal>/</literal> </entry>
6977         <entry>Scaling/rotation</entry>
6978         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
6979        </row>
6980        <row>
6981         <entry> <literal>#</literal> </entry>
6982         <entry>Point or box of intersection</entry>
6983         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
6984        </row>
6985        <row>
6986         <entry> <literal>#</literal> </entry>
6987         <entry>Number of points in path or polygon</entry>
6988         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
6989        </row>
6990        <row>
6991         <entry> <literal>@-@</literal> </entry>
6992         <entry>Length or circumference</entry>
6993         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
6994        </row>
6995        <row>
6996         <entry> <literal>@@</literal> </entry>
6997         <entry>Center</entry>
6998         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
6999        </row>
7000        <row>
7001         <entry> <literal>##</literal> </entry>
7002         <entry>Closest point to first operand on second operand</entry>
7003         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
7004        </row>
7005        <row>
7006         <entry> <literal>&lt;-&gt;</literal> </entry>
7007         <entry>Distance between</entry>
7008         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
7009        </row>
7010        <row>
7011         <entry> <literal>&amp;&amp;</literal> </entry>
7012         <entry>Overlaps?</entry>
7013         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
7014        </row>
7015        <row>
7016         <entry> <literal>&lt;&lt;</literal> </entry>
7017         <entry>Is strictly left of?</entry>
7018         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
7019        </row>
7020        <row>
7021         <entry> <literal>&gt;&gt;</literal> </entry>
7022         <entry>Is strictly right of?</entry>
7023         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
7024        </row>
7025        <row>
7026         <entry> <literal>&amp;&lt;</literal> </entry>
7027         <entry>Does not extend to the right of?</entry>
7028         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
7029        </row>
7030        <row>
7031         <entry> <literal>&amp;&gt;</literal> </entry>
7032         <entry>Does not extend to the left of?</entry>
7033         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
7034        </row>
7035        <row>
7036         <entry> <literal>&lt;&lt;|</literal> </entry>
7037         <entry>Is strictly below?</entry>
7038         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
7039        </row>
7040        <row>
7041         <entry> <literal>|&gt;&gt;</literal> </entry>
7042         <entry>Is strictly above?</entry>
7043         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
7044        </row>
7045        <row>
7046         <entry> <literal>&amp;&lt;|</literal> </entry>
7047         <entry>Does not extend above?</entry>
7048         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
7049        </row>
7050        <row>
7051         <entry> <literal>|&amp;&gt;</literal> </entry>
7052         <entry>Does not extend below?</entry>
7053         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
7054        </row>
7055        <row>
7056         <entry> <literal>&lt;^</literal> </entry>
7057         <entry>Is below (allows touching)?</entry>
7058         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
7059        </row>
7060        <row>
7061         <entry> <literal>&gt;^</literal> </entry>
7062         <entry>Is above (allows touching)?</entry>
7063         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
7064        </row>
7065        <row>
7066         <entry> <literal>?#</literal> </entry>
7067         <entry>Intersects?</entry>
7068         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7069        </row>
7070        <row>
7071         <entry> <literal>?-</literal> </entry>
7072         <entry>Is horizontal?</entry>
7073         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7074        </row>
7075        <row>
7076         <entry> <literal>?-</literal> </entry>
7077         <entry>Are horizontally aligned?</entry>
7078         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7079        </row>
7080        <row>
7081         <entry> <literal>?|</literal> </entry>
7082         <entry>Is vertical?</entry>
7083         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7084        </row>
7085        <row>
7086         <entry> <literal>?|</literal> </entry>
7087         <entry>Are vertically aligned?</entry>
7088         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7089        </row>
7090        <row>
7091         <entry> <literal>?-|</literal> </entry>
7092         <entry>Is perpendicular?</entry>
7093         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7094        </row>
7095        <row>
7096         <entry> <literal>?||</literal> </entry>
7097         <entry>Are parallel?</entry>
7098         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7099        </row>
7100        <row>
7101         <entry> <literal>@&gt;</literal> </entry>
7102         <entry>Contains?</entry>
7103         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7104        </row>
7105        <row>
7106         <entry> <literal>&lt;@</literal> </entry>
7107         <entry>Contained in or on?</entry>
7108         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7109        </row>
7110        <row>
7111         <entry> <literal>~=</literal> </entry>
7112         <entry>Same as?</entry>
7113         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7114        </row>
7115       </tbody>
7116      </tgroup>
7117    </table>
7118
7119    <note>
7120     <para>
7121      Before <productname>PostgreSQL</productname> 8.2, the containment
7122      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7123      called <literal>~</> and <literal>@</>.  These names are still
7124      available, but are deprecated and will eventually be retired.
7125     </para>
7126    </note>
7127
7128    <indexterm>
7129     <primary>area</primary>
7130    </indexterm>
7131    <indexterm>
7132     <primary>center</primary>
7133    </indexterm>
7134    <indexterm>
7135     <primary>diameter</primary>
7136    </indexterm>
7137    <indexterm>
7138     <primary>height</primary>
7139    </indexterm>
7140    <indexterm>
7141     <primary>isclosed</primary>
7142    </indexterm>
7143    <indexterm>
7144     <primary>isopen</primary>
7145    </indexterm>
7146    <indexterm>
7147     <primary>length</primary>
7148    </indexterm>
7149    <indexterm>
7150     <primary>npoints</primary>
7151    </indexterm>
7152    <indexterm>
7153     <primary>pclose</primary>
7154    </indexterm>
7155    <indexterm>
7156     <primary>popen</primary>
7157    </indexterm>
7158    <indexterm>
7159     <primary>radius</primary>
7160    </indexterm>
7161    <indexterm>
7162     <primary>width</primary>
7163    </indexterm>
7164
7165    <table id="functions-geometry-func-table">
7166      <title>Geometric Functions</title>
7167      <tgroup cols="4">
7168       <thead>
7169        <row>
7170         <entry>Function</entry>
7171         <entry>Return Type</entry>
7172         <entry>Description</entry>
7173         <entry>Example</entry>
7174        </row>
7175       </thead>
7176       <tbody>
7177        <row>
7178         <entry><literal><function>area</function>(<replaceable>object</>)</literal></entry>
7179         <entry><type>double precision</type></entry>
7180         <entry>area</entry>
7181         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7182        </row>
7183        <row>
7184         <entry><literal><function>center</function>(<replaceable>object</>)</literal></entry>
7185         <entry><type>point</type></entry>
7186         <entry>center</entry>
7187         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7188        </row>
7189        <row>
7190         <entry><literal><function>diameter</function>(<type>circle</>)</literal></entry>
7191         <entry><type>double precision</type></entry>
7192         <entry>diameter of circle</entry>
7193         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7194        </row>
7195        <row>
7196         <entry><literal><function>height</function>(<type>box</>)</literal></entry>
7197         <entry><type>double precision</type></entry>
7198         <entry>vertical size of box</entry>
7199         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7200        </row>
7201        <row>
7202         <entry><literal><function>isclosed</function>(<type>path</>)</literal></entry>
7203         <entry><type>boolean</type></entry>
7204         <entry>a closed path?</entry>
7205         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7206        </row>
7207        <row>
7208         <entry><literal><function>isopen</function>(<type>path</>)</literal></entry>
7209         <entry><type>boolean</type></entry>
7210         <entry>an open path?</entry>
7211         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7212        </row>
7213        <row>
7214         <entry><literal><function>length</function>(<replaceable>object</>)</literal></entry>
7215         <entry><type>double precision</type></entry>
7216         <entry>length</entry>
7217         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7218        </row>
7219        <row>
7220         <entry><literal><function>npoints</function>(<type>path</>)</literal></entry>
7221         <entry><type>int</type></entry>
7222         <entry>number of points</entry>
7223         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7224        </row>
7225        <row>
7226         <entry><literal><function>npoints</function>(<type>polygon</>)</literal></entry>
7227         <entry><type>int</type></entry>
7228         <entry>number of points</entry>
7229         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7230        </row>
7231        <row>
7232         <entry><literal><function>pclose</function>(<type>path</>)</literal></entry>
7233         <entry><type>path</type></entry>
7234         <entry>convert path to closed</entry>
7235         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7236        </row>
7237 <![IGNORE[
7238 <!-- Not defined by this name. Implements the intersection operator '#' -->
7239        <row>
7240         <entry><literal><function>point</function>(<type>lseg</>, <type>lseg</>)</literal></entry>
7241         <entry><type>point</type></entry>
7242         <entry>intersection</entry>
7243         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7244        </row>
7245 ]]>
7246        <row>
7247         <entry><literal><function>popen</function>(<type>path</>)</literal></entry>
7248         <entry><type>path</type></entry>
7249         <entry>convert path to open</entry>
7250         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7251        </row>
7252        <row>
7253         <entry><literal><function>radius</function>(<type>circle</type>)</literal></entry>
7254         <entry><type>double precision</type></entry>
7255         <entry>radius of circle</entry>
7256         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7257        </row>
7258        <row>
7259         <entry><literal><function>width</function>(<type>box</>)</literal></entry>
7260         <entry><type>double precision</type></entry>
7261         <entry>horizontal size of box</entry>
7262         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7263        </row>
7264       </tbody>
7265      </tgroup>
7266    </table>
7267
7268    <table id="functions-geometry-conv-table">
7269      <title>Geometric Type Conversion Functions</title>
7270      <tgroup cols="4">
7271       <thead>
7272        <row>
7273         <entry>Function</entry>
7274         <entry>Return Type</entry>
7275         <entry>Description</entry>
7276         <entry>Example</entry>
7277        </row>
7278       </thead>
7279       <tbody>
7280        <row>
7281         <entry><literal><function>box</function>(<type>circle</type>)</literal></entry>
7282         <entry><type>box</type></entry>
7283         <entry>circle to box</entry>
7284         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7285        </row>
7286        <row>
7287         <entry><literal><function>box</function>(<type>point</type>, <type>point</type>)</literal></entry>
7288         <entry><type>box</type></entry>
7289         <entry>points to box</entry>
7290         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7291        </row>
7292        <row>
7293         <entry><literal><function>box</function>(<type>polygon</type>)</literal></entry>
7294         <entry><type>box</type></entry>
7295         <entry>polygon to box</entry>
7296         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7297        </row>
7298        <row>
7299         <entry><literal><function>circle</function>(<type>box</type>)</literal></entry>
7300         <entry><type>circle</type></entry>
7301         <entry>box to circle</entry>
7302         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7303        </row>
7304        <row>
7305         <entry><literal><function>circle</function>(<type>point</type>, <type>double precision</type>)</literal></entry>
7306         <entry><type>circle</type></entry>
7307         <entry>center and radius to circle</entry>
7308         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7309        </row>
7310        <row>
7311         <entry><literal><function>circle</function>(<type>polygon</type>)</literal></entry>
7312         <entry><type>circle</type></entry>
7313         <entry>polygon to circle</entry>
7314         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7315        </row>
7316        <row>
7317         <entry><literal><function>lseg</function>(<type>box</type>)</literal></entry>
7318         <entry><type>lseg</type></entry>
7319         <entry>box diagonal to line segment</entry>
7320         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7321        </row>
7322        <row>
7323         <entry><literal><function>lseg</function>(<type>point</type>, <type>point</type>)</literal></entry>
7324         <entry><type>lseg</type></entry>
7325         <entry>points to line segment</entry>
7326         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7327        </row>
7328        <row>
7329         <entry><literal><function>path</function>(<type>polygon</type>)</literal></entry>
7330         <entry><type>point</type></entry>
7331         <entry>polygon to path</entry>
7332         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7333        </row>
7334        <row>
7335         <entry><literal><function>point</function>(<type>double
7336          precision</type>, <type>double precision</type>)</literal></entry>
7337         <entry><type>point</type></entry>
7338         <entry>construct point</entry>
7339         <entry><literal>point(23.4, -44.5)</literal></entry>
7340        </row>
7341        <row>
7342         <entry><literal><function>point</function>(<type>box</type>)</literal></entry>
7343         <entry><type>point</type></entry>
7344         <entry>center of box</entry>
7345         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7346        </row>
7347        <row>
7348         <entry><literal><function>point</function>(<type>circle</type>)</literal></entry>
7349         <entry><type>point</type></entry>
7350         <entry>center of circle</entry>
7351         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7352        </row>
7353        <row>
7354         <entry><literal><function>point</function>(<type>lseg</type>)</literal></entry>
7355         <entry><type>point</type></entry>
7356         <entry>center of line segment</entry>
7357         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7358        </row>
7359        <row>
7360         <entry><literal><function>point</function>(<type>polygon</type>)</literal></entry>
7361         <entry><type>point</type></entry>
7362         <entry>center of polygon</entry>
7363         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7364        </row>
7365        <row>
7366         <entry><literal><function>polygon</function>(<type>box</type>)</literal></entry>
7367         <entry><type>polygon</type></entry>
7368         <entry>box to 4-point polygon</entry>
7369         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7370        </row>
7371        <row>
7372         <entry><literal><function>polygon</function>(<type>circle</type>)</literal></entry>
7373         <entry><type>polygon</type></entry>
7374         <entry>circle to 12-point polygon</entry>
7375         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7376        </row>
7377        <row>
7378         <entry><literal><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</literal></entry>
7379         <entry><type>polygon</type></entry>
7380         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
7381         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7382        </row>
7383        <row>
7384         <entry><literal><function>polygon</function>(<type>path</type>)</literal></entry>
7385         <entry><type>polygon</type></entry>
7386         <entry>path to polygon</entry>
7387         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7388        </row>
7389       </tbody>
7390      </tgroup>
7391    </table>
7392
7393     <para>
7394      It is possible to access the two component numbers of a <type>point</>
7395      as though it were an array with indices 0 and 1.  For example, if
7396      <literal>t.p</> is a <type>point</> column then
7397      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7398      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7399      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7400      as an array of two <type>point</> values.
7401     </para>
7402
7403     <para>
7404      The <function>area</function> function works for the types
7405      <type>box</type>, <type>circle</type>, and <type>path</type>.
7406      The <function>area</function> function only works on the
7407      <type>path</type> data type if the points in the
7408      <type>path</type> are non-intersecting.  For example, the
7409      <type>path</type>
7410      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7411      won't work, however, the following visually identical
7412      <type>path</type>
7413      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7414      will work.  If the concept of an intersecting versus
7415      non-intersecting <type>path</type> is confusing, draw both of the
7416      above <type>path</type>s side by side on a piece of graph paper.
7417     </para>
7418
7419   </sect1>
7420
7421
7422  <sect1 id="functions-net">
7423   <title>Network Address Functions and Operators</title>
7424
7425   <para>
7426    <xref linkend="cidr-inet-operators-table"> shows the operators
7427    available for the <type>cidr</type> and <type>inet</type> types.
7428    The operators <literal>&lt;&lt;</literal>,
7429    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
7430    <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
7431    consider only the network parts of the two addresses, ignoring any
7432    host part, and determine whether one network part is identical to
7433    or a subnet of the other.
7434   </para>
7435
7436     <table id="cidr-inet-operators-table">
7437      <title><type>cidr</type> and <type>inet</type> Operators</title>
7438      <tgroup cols="3">
7439       <thead>
7440        <row>
7441         <entry>Operator</entry>
7442         <entry>Description</entry>
7443         <entry>Example</entry>
7444        </row>
7445       </thead>
7446       <tbody>
7447        <row>
7448         <entry> <literal>&lt;</literal> </entry>
7449         <entry>is less than</entry>
7450         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
7451        </row>
7452        <row>
7453         <entry> <literal>&lt;=</literal> </entry>
7454         <entry>is less than or equal</entry>
7455         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
7456        </row>
7457        <row>
7458         <entry> <literal>=</literal> </entry>
7459         <entry>equals</entry>
7460         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
7461        </row>
7462        <row>
7463         <entry> <literal>&gt;=</literal> </entry>
7464         <entry>is greater or equal</entry>
7465         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
7466        </row>
7467        <row>
7468         <entry> <literal>&gt;</literal> </entry>
7469         <entry>is greater than</entry>
7470         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
7471        </row>
7472        <row>
7473         <entry> <literal>&lt;&gt;</literal> </entry>
7474         <entry>is not equal</entry>
7475         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
7476        </row>
7477        <row>
7478         <entry> <literal>&lt;&lt;</literal> </entry>
7479         <entry>is contained within</entry>
7480         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
7481        </row>
7482        <row>
7483         <entry> <literal>&lt;&lt;=</literal> </entry>
7484         <entry>is contained within or equals</entry>
7485         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
7486        </row>
7487        <row>
7488         <entry> <literal>&gt;&gt;</literal> </entry>
7489         <entry>contains</entry>
7490         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
7491        </row>
7492        <row>
7493         <entry> <literal>&gt;&gt;=</literal> </entry>
7494         <entry>contains or equals</entry>
7495         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
7496        </row>
7497        <row>
7498         <entry> <literal>~</literal> </entry>
7499         <entry>bitwise NOT</entry>
7500         <entry><literal>~ inet '192.168.1.6'</literal></entry>
7501        </row>
7502        <row>
7503         <entry> <literal>&amp;</literal> </entry>
7504         <entry>bitwise AND</entry>
7505         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
7506        </row>
7507        <row>
7508         <entry> <literal>|</literal> </entry>
7509         <entry>bitwise OR</entry>
7510         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
7511        </row>
7512        <row>
7513         <entry> <literal>+</literal> </entry>
7514         <entry>addition</entry>
7515         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
7516        </row>
7517        <row>
7518         <entry> <literal>-</literal> </entry>
7519         <entry>subtraction</entry>
7520         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
7521        </row>
7522        <row>
7523         <entry> <literal>-</literal> </entry>
7524         <entry>subtraction</entry>
7525         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
7526        </row>
7527       </tbody>
7528      </tgroup>
7529     </table>
7530
7531   <para>
7532    <xref linkend="cidr-inet-functions-table"> shows the functions
7533    available for use with the <type>cidr</type> and <type>inet</type>
7534    types.  The <function>host</function>,
7535    <function>text</function>, and <function>abbrev</function>
7536    functions are primarily intended to offer alternative display
7537    formats.
7538   </para>
7539
7540     <table id="cidr-inet-functions-table">
7541      <title><type>cidr</type> and <type>inet</type> Functions</title>
7542      <tgroup cols="5">
7543       <thead>
7544        <row>
7545         <entry>Function</entry>
7546         <entry>Return Type</entry>
7547         <entry>Description</entry>
7548         <entry>Example</entry>
7549         <entry>Result</entry>
7550        </row>
7551       </thead>
7552       <tbody>
7553        <row>
7554         <entry><literal><function>abbrev</function>(<type>inet</type>)</literal></entry>
7555         <entry><type>text</type></entry>
7556         <entry>abbreviated display format as text</entry>
7557         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
7558         <entry><literal>10.1.0.0/16</literal></entry>
7559        </row>
7560        <row>
7561         <entry><literal><function>abbrev</function>(<type>cidr</type>)</literal></entry>
7562         <entry><type>text</type></entry>
7563         <entry>abbreviated display format as text</entry>
7564         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
7565         <entry><literal>10.1/16</literal></entry>
7566        </row>
7567        <row>
7568         <entry><literal><function>broadcast</function>(<type>inet</type>)</literal></entry>
7569         <entry><type>inet</type></entry>
7570         <entry>broadcast address for network</entry>
7571         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
7572         <entry><literal>192.168.1.255/24</literal></entry>
7573        </row>
7574        <row>
7575         <entry><literal><function>family</function>(<type>inet</type>)</literal></entry>
7576         <entry><type>int</type></entry>
7577         <entry>extract family of address; <literal>4</literal> for IPv4,
7578          <literal>6</literal> for IPv6</entry>
7579         <entry><literal>family('::1')</literal></entry>
7580         <entry><literal>6</literal></entry>
7581        </row>
7582        <row>
7583         <entry><literal><function>host</function>(<type>inet</type>)</literal></entry>
7584         <entry><type>text</type></entry>
7585         <entry>extract IP address as text</entry>
7586         <entry><literal>host('192.168.1.5/24')</literal></entry>
7587         <entry><literal>192.168.1.5</literal></entry>
7588        </row>
7589        <row>
7590         <entry><literal><function>hostmask</function>(<type>inet</type>)</literal></entry>
7591         <entry><type>inet</type></entry>
7592         <entry>construct host mask for network</entry>
7593         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
7594         <entry><literal>0.0.0.3</literal></entry>
7595        </row>
7596        <row>
7597         <entry><literal><function>masklen</function>(<type>inet</type>)</literal></entry>
7598         <entry><type>int</type></entry>
7599         <entry>extract netmask length</entry>
7600         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
7601         <entry><literal>24</literal></entry>
7602        </row>
7603        <row>
7604         <entry><literal><function>netmask</function>(<type>inet</type>)</literal></entry>
7605         <entry><type>inet</type></entry>
7606         <entry>construct netmask for network</entry>
7607         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
7608         <entry><literal>255.255.255.0</literal></entry>
7609        </row>
7610        <row>
7611         <entry><literal><function>network</function>(<type>inet</type>)</literal></entry>
7612         <entry><type>cidr</type></entry>
7613         <entry>extract network part of address</entry>
7614         <entry><literal>network('192.168.1.5/24')</literal></entry>
7615         <entry><literal>192.168.1.0/24</literal></entry>
7616        </row>
7617        <row>
7618         <entry><literal><function>set_masklen</function>(<type>inet</type>, <type>int</type>)</literal></entry>
7619         <entry><type>inet</type></entry>
7620         <entry>set netmask length for <type>inet</type> value</entry>
7621         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
7622         <entry><literal>192.168.1.5/16</literal></entry>
7623        </row>
7624        <row>
7625         <entry><literal><function>set_masklen</function>(<type>cidr</type>, <type>int</type>)</literal></entry>
7626         <entry><type>cidr</type></entry>
7627         <entry>set netmask length for <type>cidr</type> value</entry>
7628         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
7629         <entry><literal>192.168.0.0/16</literal></entry>
7630        </row>
7631        <row>
7632         <entry><literal><function>text</function>(<type>inet</type>)</literal></entry>
7633         <entry><type>text</type></entry>
7634         <entry>extract IP address and netmask length as text</entry>
7635         <entry><literal>text(inet '192.168.1.5')</literal></entry>
7636         <entry><literal>192.168.1.5/32</literal></entry>
7637        </row>
7638       </tbody>
7639      </tgroup>
7640     </table>
7641
7642   <para>
7643    Any <type>cidr</> value can be cast to <type>inet</> implicitly
7644    or explicitly; therefore, the functions shown above as operating on
7645    <type>inet</> also work on <type>cidr</> values.  (Where there are
7646    separate functions for <type>inet</> and <type>cidr</>, it is because
7647    the behavior should be different for the two cases.)
7648    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
7649    When this is done, any bits to the right of the netmask are silently zeroed
7650    to create a valid <type>cidr</> value.
7651    In addition,
7652    you can cast a text value to <type>inet</> or <type>cidr</>
7653    using normal casting syntax: for example,
7654    <literal>inet(<replaceable>expression</>)</literal> or
7655    <literal><replaceable>colname</>::cidr</literal>.
7656   </para>
7657
7658   <para>
7659    <xref linkend="macaddr-functions-table"> shows the functions
7660    available for use with the <type>macaddr</type> type.  The function
7661    <literal><function>trunc</function>(<type>macaddr</type>)</literal> returns a MAC
7662    address with the last 3 bytes set to zero.  This can be used to
7663    associate the remaining prefix with a manufacturer.
7664   </para>
7665
7666     <table id="macaddr-functions-table">
7667      <title><type>macaddr</type> Functions</title>
7668      <tgroup cols="5">
7669       <thead>
7670        <row>
7671         <entry>Function</entry>
7672         <entry>Return Type</entry>
7673         <entry>Description</entry>
7674         <entry>Example</entry>
7675         <entry>Result</entry>
7676        </row>
7677       </thead>
7678       <tbody>
7679        <row>
7680         <entry><literal><function>trunc</function>(<type>macaddr</type>)</literal></entry>
7681         <entry><type>macaddr</type></entry>
7682         <entry>set last 3 bytes to zero</entry>
7683         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
7684         <entry><literal>12:34:56:00:00:00</literal></entry>
7685        </row>
7686       </tbody>
7687      </tgroup>
7688     </table>
7689
7690    <para>
7691     The <type>macaddr</type> type also supports the standard relational
7692     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
7693     lexicographical ordering.
7694    </para>
7695
7696   </sect1>
7697
7698
7699  <sect1 id="functions-textsearch">
7700   <title>Text Search Functions and Operators</title>
7701
7702    <indexterm zone="datatype-textsearch">
7703     <primary>full text search</primary>
7704     <secondary>functions and operators</secondary>
7705    </indexterm>
7706
7707    <indexterm zone="datatype-textsearch">
7708     <primary>text search</primary>
7709     <secondary>functions and operators</secondary>
7710    </indexterm>
7711
7712   <para>
7713    <xref linkend="textsearch-operators-table">,
7714    <xref linkend="textsearch-functions-table"> and
7715    <xref linkend="textsearch-functions-debug-table">
7716    summarize the functions and operators that are provided
7717    for full text searching.  See <xref linkend="textsearch"> for a detailed
7718    explanation of <productname>PostgreSQL</productname>'s text search
7719    facility.
7720   </para>
7721
7722     <table id="textsearch-operators-table">
7723      <title>Text Search Operators</title>
7724      <tgroup cols="4">
7725       <thead>
7726        <row>
7727         <entry>Operator</entry>
7728         <entry>Description</entry>
7729         <entry>Example</entry>
7730         <entry>Result</entry>
7731        </row>
7732       </thead>
7733       <tbody>
7734        <row>
7735         <entry> <literal>@@</literal> </entry>
7736         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
7737         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
7738         <entry><literal>t</literal></entry>
7739        </row>
7740        <row>
7741         <entry> <literal>@@@</literal> </entry>
7742         <entry>deprecated synonym for <literal>@@</></entry>
7743         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
7744         <entry><literal>t</literal></entry>
7745        </row>
7746        <row>
7747         <entry> <literal>||</literal> </entry>
7748         <entry>concatenate <type>tsvector</>s</entry>
7749         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
7750         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
7751        </row>
7752        <row>
7753         <entry> <literal>&amp;&amp;</literal> </entry>
7754         <entry>AND <type>tsquery</>s together</entry>
7755         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
7756         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
7757        </row>
7758        <row>
7759         <entry> <literal>||</literal> </entry>
7760         <entry>OR <type>tsquery</>s together</entry>
7761         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
7762         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
7763        </row>
7764        <row>
7765         <entry> <literal>!!</literal> </entry>
7766         <entry>negate a <type>tsquery</></entry>
7767         <entry><literal>!! 'cat'::tsquery</literal></entry>
7768         <entry><literal>!'cat'</literal></entry>
7769        </row>
7770        <row>
7771         <entry> <literal>@&gt;</literal> </entry>
7772         <entry><type>tsquery</> contains another ?</entry>
7773         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
7774         <entry><literal>f</literal></entry>
7775        </row>
7776        <row>
7777         <entry> <literal>&lt;@</literal> </entry>
7778         <entry><type>tsquery</> is contained in ?</entry>
7779         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
7780         <entry><literal>t</literal></entry>
7781        </row>
7782       </tbody>
7783      </tgroup>
7784     </table>
7785
7786     <note>
7787      <para>
7788       The <type>tsquery</> containment operators consider only the lexemes
7789       listed in the two queries, ignoring the combining operators.
7790      </para>
7791     </note>
7792
7793     <para>
7794      In addition to the operators shown in the table, the ordinary B-tree
7795      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
7796      for types <type>tsvector</> and <type>tsquery</>.  These are not very
7797      useful for text searching but allow, for example, unique indexes to be
7798      built on columns of these types.
7799     </para>
7800
7801     <table id="textsearch-functions-table">
7802      <title>Text Search Functions</title>
7803      <tgroup cols="5">
7804       <thead>
7805        <row>
7806         <entry>Function</entry>
7807         <entry>Return Type</entry>
7808         <entry>Description</entry>
7809         <entry>Example</entry>
7810         <entry>Result</entry>
7811        </row>
7812       </thead>
7813       <tbody>
7814        <row>
7815         <entry><literal><function>to_tsvector</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</literal></entry>
7816         <entry><type>tsvector</type></entry>
7817         <entry>reduce document text to <type>tsvector</></entry>
7818         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
7819         <entry><literal>'fat':2 'rat':3</literal></entry>
7820        </row>
7821        <row>
7822         <entry><literal><function>length</function>(<type>tsvector</>)</literal></entry>
7823         <entry><type>integer</type></entry>
7824         <entry>number of lexemes in <type>tsvector</></entry>
7825         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7826         <entry><literal>3</literal></entry>
7827        </row>
7828        <row>
7829         <entry><literal><function>setweight</function>(<type>tsvector</>, <type>"char"</>)</literal></entry>
7830         <entry><type>tsvector</type></entry>
7831         <entry>assign weight to each element of <type>tsvector</></entry>
7832         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
7833         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
7834        </row>
7835        <row>
7836         <entry><literal><function>strip</function>(<type>tsvector</>)</literal></entry>
7837         <entry><type>tsvector</type></entry>
7838         <entry>remove positions and weights from <type>tsvector</></entry>
7839         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7840         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
7841        </row>
7842        <row>
7843         <entry><literal><function>to_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7844         <entry><type>tsquery</type></entry>
7845         <entry>normalize words and convert to <type>tsquery</></entry>
7846         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
7847         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7848        </row>
7849        <row>
7850         <entry><literal><function>plainto_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7851         <entry><type>tsquery</type></entry>
7852         <entry>produce <type>tsquery</> ignoring punctuation</entry>
7853         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
7854         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7855        </row>
7856        <row>
7857         <entry><literal><function>numnode</function>(<type>tsquery</>)</literal></entry>
7858         <entry><type>integer</type></entry>
7859         <entry>number of lexemes plus operators in <type>tsquery</></entry>
7860         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
7861         <entry><literal>5</literal></entry>
7862        </row>
7863        <row>
7864         <entry><literal><function>querytree</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</literal></entry>
7865         <entry><type>text</type></entry>
7866         <entry>get indexable part of a <type>tsquery</></entry>
7867         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
7868         <entry><literal>'foo'</literal></entry>
7869        </row>
7870        <row>
7871         <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>
7872         <entry><type>float4</type></entry>
7873         <entry>rank document for query</entry>
7874         <entry><literal>ts_rank(textsearch, query)</literal></entry>
7875         <entry><literal>0.818</literal></entry>
7876        </row>
7877        <row>
7878         <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>
7879         <entry><type>float4</type></entry>
7880         <entry>rank document for query using cover density</entry>
7881         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
7882         <entry><literal>2.01317</literal></entry>
7883        </row>
7884        <row>
7885         <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>
7886         <entry><type>text</type></entry>
7887         <entry>display a query match</entry>
7888         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
7889         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
7890        </row>
7891        <row>
7892         <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>
7893         <entry><type>tsquery</type></entry>
7894         <entry>replace target with substitute within query</entry>
7895         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
7896         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7897        </row>
7898        <row>
7899         <entry><literal><function>ts_rewrite</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</literal></entry>
7900         <entry><type>tsquery</type></entry>
7901         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
7902         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
7903         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7904        </row>
7905        <row>
7906         <entry><literal><function>get_current_ts_config</function>()</literal></entry>
7907         <entry><type>regconfig</type></entry>
7908         <entry>get default text search configuration</entry>
7909         <entry><literal>get_current_ts_config()</literal></entry>
7910         <entry><literal>english</literal></entry>
7911        </row>
7912        <row>
7913         <entry><literal><function>tsvector_update_trigger</function>()</literal></entry>
7914         <entry><type>trigger</type></entry>
7915         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7916         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
7917         <entry><literal></literal></entry>
7918        </row>
7919        <row>
7920         <entry><literal><function>tsvector_update_trigger_column</function>()</literal></entry>
7921         <entry><type>trigger</type></entry>
7922         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7923         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
7924         <entry><literal></literal></entry>
7925         <entry><literal></literal></entry>
7926        </row>
7927       </tbody>
7928      </tgroup>
7929     </table>
7930
7931   <note>
7932    <para>
7933     All the text search functions that accept an optional <type>regconfig</>
7934     argument will use the configuration specified by
7935     <xref linkend="guc-default-text-search-config">
7936     when that argument is omitted.
7937    </para>
7938   </note>
7939
7940   <para>
7941    The functions in
7942    <xref linkend="textsearch-functions-debug-table">
7943    are listed separately because they are not usually used in everyday text
7944    searching operations.  They are helpful for development and debugging
7945    of new text search configurations.
7946   </para>
7947
7948     <table id="textsearch-functions-debug-table">
7949      <title>Text Search Debugging Functions</title>
7950      <tgroup cols="5">
7951       <thead>
7952        <row>
7953         <entry>Function</entry>
7954         <entry>Return Type</entry>
7955         <entry>Description</entry>
7956         <entry>Example</entry>
7957         <entry>Result</entry>
7958        </row>
7959       </thead>
7960       <tbody>
7961        <row>
7962         <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>
7963         <entry><type>setof record</type></entry>
7964         <entry>test a configuration</entry>
7965         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
7966         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
7967        </row>
7968        <row>
7969         <entry><literal><function>ts_lexize</function>(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</literal></entry>
7970         <entry><type>text[]</type></entry>
7971         <entry>test a dictionary</entry>
7972         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
7973         <entry><literal>{star}</literal></entry>
7974        </row>
7975        <row>
7976         <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>
7977         <entry><type>setof record</type></entry>
7978         <entry>test a parser</entry>
7979         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
7980         <entry><literal>(1,foo) ...</literal></entry>
7981        </row>
7982        <row>
7983         <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>
7984         <entry><type>setof record</type></entry>
7985         <entry>test a parser</entry>
7986         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
7987         <entry><literal>(1,foo) ...</literal></entry>
7988        </row>
7989        <row>
7990         <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>
7991         <entry><type>setof record</type></entry>
7992         <entry>get token types defined by parser</entry>
7993         <entry><literal>ts_token_type('default')</literal></entry>
7994         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
7995        </row>
7996        <row>
7997         <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>
7998         <entry><type>setof record</type></entry>
7999         <entry>get token types defined by parser</entry>
8000         <entry><literal>ts_token_type(3722)</literal></entry>
8001         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8002        </row>
8003        <row>
8004         <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>
8005         <entry><type>setof record</type></entry>
8006         <entry>get statistics of a <type>tsvector</> column</entry>
8007         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
8008         <entry><literal>(foo,10,15) ...</literal></entry>
8009        </row>
8010       </tbody>
8011      </tgroup>
8012     </table>
8013
8014  </sect1>
8015
8016
8017  <sect1 id="functions-xml">
8018   <title>XML Functions</title>
8019
8020   <para>
8021    The functions and function-like expressions described in this
8022    section operate on values of type <type>xml</type>.  Check <xref
8023    linkend="datatype-xml"> for information about the <type>xml</type>
8024    type.  The function-like expressions <function>xmlparse</function>
8025    and <function>xmlserialize</function> for converting to and from
8026    type <type>xml</type> are not repeated here.  Use of many of these
8027    functions requires the installation to have been built
8028    with <command>configure --with-libxml</>.
8029   </para>
8030
8031   <sect2>
8032    <title>Producing XML Content</title>
8033
8034    <para>
8035     A set of functions and function-like expressions are available for
8036     producing XML content from SQL data.  As such, they are
8037     particularly suitable for formatting query results into XML
8038     documents for processing in client applications.
8039    </para>
8040
8041    <sect3>
8042     <title><literal>xmlcomment</literal></title>
8043
8044     <indexterm>
8045      <primary>xmlcomment</primary>
8046     </indexterm>
8047
8048 <synopsis>
8049 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8050 </synopsis>
8051
8052     <para>
8053      The function <function>xmlcomment</function> creates an XML value
8054      containing an XML comment with the specified text as content.
8055      The text cannot contain <literal>--</literal> or end with a
8056      <literal>-</literal> so that the resulting construct is a valid
8057      XML comment.  If the argument is null, the result is null.
8058     </para>
8059
8060     <para>
8061      Example:
8062 <screen><![CDATA[
8063 SELECT xmlcomment('hello');
8064
8065   xmlcomment
8066 --------------
8067  <!--hello-->
8068 ]]></screen>
8069     </para>
8070    </sect3>
8071
8072    <sect3>
8073     <title><literal>xmlconcat</literal></title>
8074
8075     <indexterm>
8076      <primary>xmlconcat</primary>
8077     </indexterm>
8078
8079  <synopsis>
8080  <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8081  </synopsis>
8082  
8083     <para>
8084      The function <function>xmlconcat</function> concatenates a list
8085      of individual XML values to create a single value containing an
8086      XML content fragment.  Null values are omitted; the result is
8087      only null if there are no nonnull arguments.
8088     </para>
8089
8090     <para>
8091      Example:
8092 <screen><![CDATA[
8093 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8094
8095       xmlconcat
8096 ----------------------
8097  <abc/><bar>foo</bar>
8098 ]]></screen>
8099     </para>
8100
8101     <para>
8102      XML declarations, if present, are combined as follows.  If all
8103      argument values have the same XML version declaration, that
8104      version is used in the result, else no version is used.  If all
8105      argument values have the standalone declaration value
8106      <quote>yes</quote>, then that value is used in the result.  If
8107      all argument values have a standalone declaration value and at
8108      least one is <quote>no</quote>, then that is used in the result.
8109      Else the result will have no standalone declaration.  If the
8110      result is determined to require a standalone declaration but no
8111      version declaration, a version declaration with version 1.0 will
8112      be used because XML requires an XML declaration to contain a
8113      version declaration.  Encoding declarations are ignored and
8114      removed in all cases.
8115     </para>
8116
8117     <para>
8118      Example:
8119 <screen><![CDATA[
8120 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
8121
8122              xmlconcat
8123 -----------------------------------
8124  <?xml version="1.1"?><foo/><bar/>
8125 ]]></screen>
8126     </para>
8127    </sect3>
8128  
8129    <sect3>
8130     <title><literal>xmlelement</literal></title>
8131  
8132    <indexterm>
8133     <primary>xmlelement</primary>
8134    </indexterm>
8135  
8136 <synopsis>
8137  <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>)
8138  </synopsis>
8139  
8140     <para>
8141      The <function>xmlelement</function> expression produces an XML
8142      element with the given name, attributes, and content.
8143     </para>
8144
8145     <para>
8146      Examples:
8147 <screen><![CDATA[
8148 SELECT xmlelement(name foo);
8149
8150  xmlelement
8151 ------------
8152  <foo/>
8153
8154 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8155
8156     xmlelement
8157 ------------------
8158  <foo bar="xyz"/>
8159
8160 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8161
8162              xmlelement
8163 -------------------------------------
8164  <foo bar="2007-01-26">content</foo>
8165 ]]></screen>
8166     </para>
8167
8168     <para>
8169      Element and attribute names that are not valid XML names are
8170      escaped by replacing the offending characters by the sequence
8171      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8172      <replaceable>HHHH</replaceable> is the character's Unicode
8173      codepoint in hexadecimal notation.  For example:
8174 <screen><![CDATA[
8175 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
8176
8177             xmlelement
8178 ----------------------------------
8179  <foo_x0024_bar a_x0026_b="xyz"/>
8180 ]]></screen>
8181     </para>
8182
8183     <para>
8184      An explicit attribute name need not be specified if the attribute
8185      value is a column reference, in which case the column's name will
8186      be used as attribute name by default.  In any other case, the
8187      attribute must be given an explicit name.  So this example is
8188      valid:
8189 <screen>
8190 CREATE TABLE test (a xml, b xml);
8191 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8192 </screen>
8193      But these are not:
8194 <screen>
8195 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8196 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8197 </screen>
8198     </para>
8199
8200     <para>
8201      Element content, if specified, will be formatted according to
8202      data type.  If the content is itself of type <type>xml</type>,
8203      complex XML documents can be constructed.  For example:
8204 <screen><![CDATA[
8205 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8206                             xmlelement(name abc),
8207                             xmlcomment('test'),
8208                             xmlelement(name xyz));
8209
8210                   xmlelement
8211 ----------------------------------------------
8212  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
8213 ]]></screen>
8214
8215      Content of other types will be formatted into valid XML character
8216      data.  This means in particular that the characters &lt;, &gt;,
8217      and &amp; will be converted to entities.  Binary data (data type
8218      <type>bytea</type>) will be represented in base64 or hex
8219      encoding, depending on the setting of the configuration parameter
8220      <xref linkend="guc-xmlbinary">.  The particular behavior for
8221      individual data types is expected to evolve in order to align the
8222      SQL and PostgreSQL data types with the XML Schema specification,
8223      at which point a more precise description will appear.
8224     </para>
8225    </sect3>
8226  
8227    <sect3>
8228     <title><literal>xmlforest</literal></title>
8229  
8230    <indexterm>
8231     <primary>xmlforest</primary>
8232    </indexterm>
8233  
8234  <synopsis>
8235  <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8236  </synopsis>
8237  
8238     <para>
8239      The <function>xmlforest</function> expression produces an XML
8240      forest (sequence) of elements using the given names and content.
8241     </para>
8242
8243     <para>
8244      Examples:
8245 <screen><![CDATA[
8246 SELECT xmlforest('abc' AS foo, 123 AS bar);
8247
8248           xmlforest
8249 ------------------------------
8250  <foo>abc</foo><bar>123</bar>
8251
8252
8253 SELECT xmlforest(table_name, column_name) FROM information_schema.columns WHERE table_schema = 'pg_catalog';
8254
8255                                          xmlforest
8256 -------------------------------------------------------------------------------------------
8257  <table_name>pg_authid</table_name><column_name>rolname</column_name>
8258  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8259  ...
8260 ]]></screen>
8261
8262      As seen in the second example, the element name can be omitted if
8263      the content value is a column reference, in which case the column
8264      name is used by default.  Otherwise, a name must be specified.
8265     </para>
8266
8267     <para>
8268      Element names that are not valid XML names are escaped as shown
8269      for <function>xmlelement</function> above.  Similarly, content
8270      data is escaped to make valid XML content, unless it is already
8271      of type <type>xml</type>.
8272     </para>
8273
8274     <para>
8275      Note that XML forests are not valid XML documents if they consist
8276      of more than one element.  So it might be useful to wrap
8277      <function>xmlforest</function> expressions in
8278      <function>xmlelement</function>.
8279     </para>
8280    </sect3>
8281  
8282    <sect3>
8283     <title><literal>xmlpi</literal></title>
8284  
8285    <indexterm>
8286     <primary>xmlpi</primary>
8287    </indexterm>
8288  
8289  <synopsis>
8290  <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
8291  </synopsis>
8292  
8293     <para>
8294      The <function>xmlpi</function> expression creates an XML
8295      processing instruction.  The content, if present, must not
8296      contain the character sequence <literal>?&gt;</literal>.
8297     </para>
8298
8299     <para>
8300      Example:
8301 <screen><![CDATA[
8302 SELECT xmlpi(name php, 'echo "hello world";');
8303
8304             xmlpi
8305 -----------------------------
8306  <?php echo "hello world";?>
8307 ]]></screen>
8308     </para>
8309    </sect3>
8310  
8311    <sect3>
8312     <title><literal>xmlroot</literal></title>
8313  
8314    <indexterm>
8315     <primary>xmlroot</primary>
8316    </indexterm>
8317  
8318  <synopsis>
8319  <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable>|no value <optional>, standalone yes|no|no value</optional>)
8320  </synopsis>
8321  
8322     <para>
8323      The <function>xmlroot</function> expression alters the properties
8324      of the root node of an XML value.  If a version is specified,
8325      this replaces the value in the version declaration, if a
8326      standalone value is specified, this replaces the value in the
8327      standalone declaration.
8328     </para>
8329
8330     <para>
8331 <screen><![CDATA[
8332 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'), version '1.0', standalone yes);
8333
8334                 xmlroot
8335 ----------------------------------------
8336  <?xml version="1.0" standalone="yes"?>
8337  <content>abc</content>
8338 ]]></screen>
8339     </para>
8340    </sect3>
8341
8342    <sect3>
8343     <title><literal>xmlagg</literal></title>
8344
8345     <indexterm>
8346      <primary>xmlagg</primary>
8347     </indexterm>
8348
8349 <synopsis>
8350 <function>xmlagg</function>(<replaceable>xml</replaceable>)
8351 </synopsis>
8352
8353     <para>
8354      The function <function>xmlagg</function> is, unlike the other
8355      functions below, an aggregate function.  It concatenates the
8356      input values to the aggregate function call,
8357      like <function>xmlconcat</function> does.
8358      See <xref linkend="functions-aggregate"> for general information
8359      about aggregate functions.
8360     </para>
8361
8362     <para>
8363      Example:
8364 <screen><![CDATA[
8365 CREATE TABLE test (y int, x xml);
8366 INSERT INTO test VALUES (1, '<foo>abc</foo>');
8367 INSERT INTO test VALUES (2, '<bar/>');
8368 SELECT xmlagg(x) FROM test;
8369         xmlagg
8370 ----------------------
8371  <foo>abc</foo><bar/>
8372 ]]></screen>
8373     </para>
8374
8375     <para>
8376      Note that in the current implementation, the order of the
8377      concatenation is in principle undefined.  Making the input values
8378      to be sorted in some other way will usually work, however.  For
8379      instance, in the above example, one could influence the order
8380      like so:
8381 <screen><![CDATA[
8382 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
8383         xmlagg
8384 ----------------------
8385  <bar/><foo>abc</foo>
8386 ]]></screen>
8387
8388      But this approach is not guaranteed to work in all situations and
8389      in all versions of PostgreSQL.  A future version of PostgreSQL
8390      will probably provide an additional feature to control the order
8391      in a proper way (<literal>xmlagg(expr ORDER BY expr, expr,
8392      ...</literal>).
8393     </para>
8394    </sect3>
8395
8396    <sect3>
8397     <title>XML Predicates</title>
8398
8399     <indexterm>
8400      <primary>IS DOCUMENT</primary>
8401     </indexterm>
8402
8403 <synopsis>
8404 <replaceable>xml</replaceable> IS DOCUMENT
8405 </synopsis>
8406
8407     <para>
8408      The expression <literal>IS DOCUMENT</literal> returns true if the
8409      argument XML value is a proper XML document, false if it is not
8410      (that is, it is a content fragment), or null if the argument is
8411      null.  See <xref linkend="datatype-xml"> about the difference
8412      between documents and content fragments.
8413     </para>
8414    </sect3>
8415   </sect2>
8416
8417   <sect2 id="functions-xml-processing">
8418    <title>Processing XML</title>
8419
8420    <indexterm>
8421     <primary>XPath</primary>
8422    </indexterm>
8423
8424    <para>
8425     To process values of data type <type>xml</type>, PostgreSQL offers
8426     the function <function>xpath</function>, which evaluates XPath 1.0
8427     expressions.
8428    </para>
8429
8430 <synopsis>
8431 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable><optional>, <replaceable>nsarray</replaceable></optional>)
8432 </synopsis>
8433
8434    <para>
8435     The function <function>xpath</function> evaluates the XPath
8436     expression <replaceable>xpath</replaceable> against the XML value
8437     <replaceable>xml</replaceable>.  It returns an array of XML values
8438     corresponding to the node set produced by the XPath expression.
8439    </para>
8440
8441    <para>
8442     The third argument of the function is an array of namespace
8443     mappings.  This array should be a two-dimensional array with the
8444     length of the second axis being equal to 2 (i.e., it should be an
8445     array of arrays, each of which consists of exactly 2 elements).
8446     The first element of each array entry is the namespace name, the
8447     second the namespace URI.
8448    </para>
8449
8450    <para>
8451     Example:
8452 <screen><![CDATA[
8453 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', ARRAY[ARRAY['my', 'http://example.com']]);
8454
8455  xpath  
8456 --------
8457  {test}
8458 (1 row)
8459 ]]></screen>
8460    </para>
8461   </sect2>
8462
8463   <sect2 id="functions-xml-mapping">
8464    <title>Mapping Tables to XML</title>
8465
8466    <indexterm zone="functions-xml-mapping"> 
8467     <primary>XML export</primary>
8468    </indexterm>
8469
8470    <para>
8471     The following functions map the contents of relational tables to
8472     XML values.  They can be thought of as XML export functionality.
8473 <synopsis>
8474 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8475 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
8476 cursor_to_xml(cursor refcursor, count int, nulls boolean, tableforest boolean, targetns text)
8477 </synopsis>
8478     The return type of each function is <type>xml</type>.
8479    </para>
8480
8481    <para>
8482     <function>table_to_xml</function> maps the content of the named
8483     table, passed as parameter <parameter>tbl</parameter>.  The
8484     <type>regclass</type> type accepts strings identifying tables using the
8485     usual notation, including optional schema qualifications and
8486     double quotes.  <function>query_to_xml</function> executes the
8487     query whose text is passed as parameter
8488     <parameter>query</parameter> and maps the result set.
8489     <function>cursor_to_xml</function> fetches the indicated number of
8490     rows from the cursor specified by the parameter
8491     <parameter>cursor</parameter>.  This variant is recommendable if
8492     large tables have to be mapped, because the result value is built
8493     up in memory by each function.
8494    </para>
8495
8496    <para>
8497     If <parameter>tableforest</parameter> is false, then the resulting
8498     XML document looks like this:
8499 <screen><![CDATA[
8500 <tablename>
8501   <row>
8502     <columnname1>data</columnname1>
8503     <columnname2>data</columnname2>
8504   </row>
8505
8506   <row>
8507     ...
8508   </row>
8509
8510   ...
8511 </tablename>
8512 ]]></screen>
8513
8514     If <parameter>tableforest</parameter> is true, the result is an
8515     XML content fragment that looks like this:
8516 <screen><![CDATA[
8517 <tablename>
8518   <columnname1>data</columnname1>
8519   <columnname2>data</columnname2>
8520 </tablename>
8521
8522 <tablename>
8523   ...
8524 </tablename>
8525
8526 ...
8527 ]]></screen>
8528
8529     If no table name is available, that is, when mapping a query or a
8530     cursor, the string <literal>table</literal> is used in the first
8531     format, <literal>row</literal> in the second format.
8532    </para>
8533
8534    <para>
8535     The choice between these formats is up to the user.  The first
8536     format is a proper XML document, which will be important in many
8537     applications.  The second format tends to be more useful in the
8538     <function>cursor_to_xml</function> function if the result values are to be
8539     reassembled into one document later on.  The functions for
8540     producing XML content discussed above, in particular
8541     <function>xmlelement</function>, can be used to alter the results
8542     to taste.
8543    </para>
8544
8545    <para>
8546     The data values are mapped in the same way as described for the
8547     function <function>xmlelement</function> above.
8548    </para>
8549
8550    <para>
8551     The parameter <parameter>nulls</parameter> determines whether null
8552     values should be included in the output.  If true, null values in
8553     columns are represented as
8554 <screen><![CDATA[
8555 <columnname xsi:nil="true"/>
8556 ]]></screen>
8557     where <literal>xsi</literal> is the XML namespace prefix for XML
8558     Schema Instance.  An appropriate namespace declaration will be
8559     added to the result value.  If false, columns containing null
8560     values are simply omitted from the output.
8561    </para>
8562
8563    <para>
8564     The parameter <parameter>targetns</parameter> specifies the
8565     desired XML namespace of the result.  If no particular namespace
8566     is wanted, an empty string should be passed.
8567    </para>
8568
8569    <para>
8570     The following functions return XML Schema documents describing the
8571     mappings made by the data mappings produced by the corresponding
8572     functions above.
8573 <synopsis>
8574 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8575 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8576 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
8577 </synopsis>
8578     It is essential that the same parameters are passed in order to
8579     obtain matching XML data mappings and XML Schema documents.
8580    </para>
8581
8582    <para>
8583     The following functions produce XML data mappings and the
8584     corresponding XML Schema in one document (or forest), linked
8585     together.  They can be useful where self-contained and
8586     self-describing results are wanted.
8587 <synopsis>
8588 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8589 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8590 </synopsis>
8591    </para>
8592
8593    <para>
8594     In addition, the following functions are available to produce
8595     analogous mappings of entire schemas or the entire current
8596     database.
8597 <synopsis>
8598 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
8599 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8600 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8601
8602 database_to_xml(nulls boolean, tableforest boolean, targetns text)
8603 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
8604 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
8605 </synopsis>
8606
8607     Note that these potentially produce a lot of data, which needs to
8608     be built up in memory.  When requesting content mappings of large
8609     schemas or databases, it may be worthwhile to consider mapping the
8610     tables separately instead, possibly even through a cursor.
8611    </para>
8612
8613    <para>
8614     The result of a schema content mapping looks like this:
8615
8616 <screen><![CDATA[
8617 <schemaname>
8618
8619 table1-mapping
8620
8621 table2-mapping
8622
8623 ...
8624
8625 </schemaname>]]></screen>
8626
8627     where the format of a table mapping depends on the
8628     <parameter>tableforest</parameter> parameter as explained above.
8629    </para>
8630
8631    <para>
8632     The result of a database content mapping looks like this:
8633
8634 <screen><![CDATA[
8635 <dbname>
8636
8637 <schema1name>
8638   ...
8639 </schema1name>
8640
8641 <schema2name>
8642   ...
8643 </schema2name>
8644
8645 ...
8646
8647 </dbname>]]></screen>
8648
8649     where the schema mapping is as above.
8650    </para>
8651
8652    <para>
8653     As an example for using the output produced by these functions,
8654     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
8655     converts the output of
8656     <function>table_to_xml_and_xmlschema</function> to an HTML
8657     document containing a tabular rendition of the table data.  In a
8658     similar manner, the result data of these functions can be
8659     converted into other XML-based formats.
8660    </para>
8661
8662    <figure id="xslt-xml-html">
8663     <title>XSLT stylesheet for converting SQL/XML output to HTML</title>
8664 <programlisting><![CDATA[
8665 <?xml version="1.0"?>
8666 <xsl:stylesheet version="1.0"
8667     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
8668     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
8669     xmlns="http://www.w3.org/1999/xhtml"
8670 >
8671
8672   <xsl:output method="xml"
8673       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
8674       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
8675       indent="yes"/>
8676
8677   <xsl:template match="/*">
8678     <xsl:variable name="schema" select="//xsd:schema"/>
8679     <xsl:variable name="tabletypename"
8680                   select="$schema/xsd:element[@name=name(current())]/@type"/>
8681     <xsl:variable name="rowtypename"
8682                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
8683
8684     <html>
8685       <head>
8686         <title><xsl:value-of select="name(current())"/></title>
8687       </head>
8688       <body>
8689         <table>
8690           <tr>
8691             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
8692               <th><xsl:value-of select="."/></th>
8693             </xsl:for-each>
8694           </tr>
8695
8696           <xsl:for-each select="row">
8697             <tr>
8698               <xsl:for-each select="*">
8699                 <td><xsl:value-of select="."/></td>
8700               </xsl:for-each>
8701             </tr>
8702           </xsl:for-each>
8703         </table>
8704       </body>
8705     </html>
8706   </xsl:template>
8707
8708 </xsl:stylesheet>
8709 ]]></programlisting>
8710    </figure>
8711   </sect2>
8712  </sect1>
8713
8714
8715  <sect1 id="functions-sequence">
8716   <title>Sequence Manipulation Functions</title>
8717
8718   <indexterm>
8719    <primary>sequence</primary>
8720   </indexterm>
8721   <indexterm>
8722    <primary>nextval</primary>
8723   </indexterm>
8724   <indexterm>
8725    <primary>currval</primary>
8726   </indexterm>
8727   <indexterm>
8728    <primary>lastval</primary>
8729   </indexterm>
8730   <indexterm>
8731    <primary>setval</primary>
8732   </indexterm>
8733
8734   <para>
8735    This section describes <productname>PostgreSQL</productname>'s
8736    functions for operating on <firstterm>sequence objects</firstterm>.
8737    Sequence objects (also called sequence generators or just
8738    sequences) are special single-row tables created with <xref
8739    linkend="sql-createsequence" endterm="sql-createsequence-title">.
8740    A sequence object is usually used to generate unique identifiers
8741    for rows of a table.  The sequence functions, listed in <xref
8742    linkend="functions-sequence-table">, provide simple, multiuser-safe
8743    methods for obtaining successive sequence values from sequence
8744    objects.
8745   </para>
8746
8747    <table id="functions-sequence-table">
8748     <title>Sequence Functions</title>
8749     <tgroup cols="3">
8750      <thead>
8751       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
8752      </thead>
8753
8754      <tbody>
8755       <row>
8756         <entry><literal><function>currval</function>(<type>regclass</type>)</literal></entry>
8757         <entry><type>bigint</type></entry>
8758         <entry>Return value most recently obtained with
8759         <function>nextval</function> for specified sequence</entry>
8760       </row>
8761       <row>
8762         <entry><literal><function>lastval</function>()</literal></entry>
8763         <entry><type>bigint</type></entry>
8764         <entry>Return value most recently obtained with
8765         <function>nextval</function> for any sequence</entry>
8766       </row>
8767       <row>
8768         <entry><literal><function>nextval</function>(<type>regclass</type>)</literal></entry>
8769         <entry><type>bigint</type></entry>
8770         <entry>Advance sequence and return new value</entry>
8771       </row>
8772       <row>
8773         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>)</literal></entry>
8774         <entry><type>bigint</type></entry>
8775         <entry>Set sequence's current value</entry>
8776       </row>
8777       <row>
8778         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</literal></entry>
8779         <entry><type>bigint</type></entry>
8780         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
8781       </row>
8782      </tbody>
8783     </tgroup>
8784    </table>
8785
8786   <para>
8787    The sequence to be operated on by a sequence-function call is specified by
8788    a <type>regclass</> argument, which is just the OID of the sequence in the
8789    <structname>pg_class</> system catalog.  You do not have to look up the
8790    OID by hand, however, since the <type>regclass</> data type's input
8791    converter will do the work for you.  Just write the sequence name enclosed
8792    in single quotes, so that it looks like a literal constant.  To
8793    achieve some compatibility with the handling of ordinary
8794    <acronym>SQL</acronym> names, the string will be converted to lowercase
8795    unless it contains double quotes around the sequence name.  Thus:
8796 <programlisting>
8797 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
8798 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
8799 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
8800 </programlisting>
8801    The sequence name can be schema-qualified if necessary:
8802 <programlisting>
8803 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
8804 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
8805 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
8806 </programlisting>
8807    See <xref linkend="datatype-oid"> for more information about
8808    <type>regclass</>.
8809   </para>
8810
8811   <note>
8812    <para>
8813     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
8814     sequence functions were of type <type>text</>, not <type>regclass</>, and
8815     the above-described conversion from a text string to an OID value would
8816     happen at run time during each call.  For backwards compatibility, this
8817     facility still exists, but internally it is now handled as an implicit
8818     coercion from <type>text</> to <type>regclass</> before the function is
8819     invoked.
8820    </para>
8821
8822    <para>
8823     When you write the argument of a sequence function as an unadorned
8824     literal string, it becomes a constant of type <type>regclass</>.
8825     Since this is really just an OID, it will track the originally
8826     identified sequence despite later renaming, schema reassignment,
8827     etc.  This <quote>early binding</> behavior is usually desirable for
8828     sequence references in column defaults and views.  But sometimes you will
8829     want <quote>late binding</> where the sequence reference is resolved
8830     at run time.  To get late-binding behavior, force the constant to be
8831     stored as a <type>text</> constant instead of <type>regclass</>:
8832 <programlisting>
8833 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
8834 </programlisting>
8835     Note that late binding was the only behavior supported in
8836     <productname>PostgreSQL</productname> releases before 8.1, so you
8837     might need to do this to preserve the semantics of old applications.
8838    </para>
8839
8840    <para>
8841     Of course, the argument of a sequence function can be an expression
8842     as well as a constant.  If it is a text expression then the implicit
8843     coercion will result in a run-time lookup.
8844    </para>
8845   </note>
8846
8847   <para>
8848    The available sequence functions are:
8849
8850     <variablelist>
8851      <varlistentry>
8852       <term><function>nextval</function></term>
8853       <listitem>
8854        <para>
8855         Advance the sequence object to its next value and return that
8856         value.  This is done atomically: even if multiple sessions
8857         execute <function>nextval</function> concurrently, each will safely receive
8858         a distinct sequence value.
8859        </para>
8860       </listitem>
8861      </varlistentry>
8862
8863      <varlistentry>
8864       <term><function>currval</function></term>
8865       <listitem>
8866        <para>
8867         Return the value most recently obtained by <function>nextval</function>
8868         for this sequence in the current session.  (An error is
8869         reported if <function>nextval</function> has never been called for this
8870         sequence in this session.)  Notice that because this is returning
8871         a session-local value, it gives a predictable answer whether or not
8872         other sessions have executed <function>nextval</function> since the
8873         current session did.
8874        </para>
8875       </listitem>
8876      </varlistentry>
8877
8878      <varlistentry>
8879       <term><function>lastval</function></term>
8880       <listitem>
8881        <para>
8882         Return the value most recently returned by
8883         <function>nextval</> in the current session. This function is
8884         identical to <function>currval</function>, except that instead
8885         of taking the sequence name as an argument it fetches the
8886         value of the last sequence that <function>nextval</function>
8887         was used on in the current session. It is an error to call
8888         <function>lastval</function> if <function>nextval</function>
8889         has not yet been called in the current session.
8890        </para>
8891       </listitem>
8892      </varlistentry>
8893
8894      <varlistentry>
8895       <term><function>setval</function></term>
8896       <listitem>
8897        <para>
8898         Reset the sequence object's counter value.  The two-parameter
8899         form sets the sequence's <literal>last_value</literal> field to the
8900         specified value and sets its <literal>is_called</literal> field to
8901         <literal>true</literal>, meaning that the next
8902         <function>nextval</function> will advance the sequence before
8903         returning a value.  The value reported by <function>currval</> is
8904         also set to the specified value.  In the three-parameter form,
8905         <literal>is_called</literal> can be set either <literal>true</literal>
8906         or <literal>false</literal>.  <literal>true</> has the same effect as
8907         the two-parameter form. If it's set to <literal>false</literal>, the
8908         next <function>nextval</function> will return exactly the specified
8909         value, and sequence advancement commences with the following
8910         <function>nextval</function>.  Furthermore, the value reported by
8911         <function>currval</> is not changed in this case (this is a change
8912         from pre-8.3 behavior).  For example,
8913
8914 <screen>
8915 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
8916 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
8917 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
8918 </screen>
8919
8920         The result returned by <function>setval</function> is just the value of its
8921         second argument.
8922        </para>
8923       </listitem>
8924      </varlistentry>
8925     </variablelist>
8926   </para>
8927
8928   <para>
8929    If a sequence object has been created with default parameters,
8930    <function>nextval</function> calls on it will return successive values
8931    beginning with 1.  Other behaviors can be obtained by using
8932    special parameters in the <xref linkend="sql-createsequence" endterm="sql-createsequence-title"> command;
8933    see its command reference page for more information.
8934   </para>
8935
8936   <important>
8937    <para>
8938     To avoid blocking of concurrent transactions that obtain numbers from the
8939     same sequence, a <function>nextval</function> operation is never rolled back;
8940     that is, once a value has been fetched it is considered used, even if the
8941     transaction that did the <function>nextval</function> later aborts.  This means
8942     that aborted transactions might leave unused <quote>holes</quote> in the
8943     sequence of assigned values.  <function>setval</function> operations are never
8944     rolled back, either.
8945    </para>
8946   </important>
8947
8948  </sect1>
8949
8950
8951  <sect1 id="functions-conditional">
8952   <title>Conditional Expressions</title>
8953
8954   <indexterm>
8955    <primary>CASE</primary>
8956   </indexterm>
8957
8958   <indexterm>
8959    <primary>conditional expression</primary>
8960   </indexterm>
8961
8962   <para>
8963    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
8964    available in <productname>PostgreSQL</productname>.
8965   </para>
8966
8967   <tip>
8968    <para>
8969     If your needs go beyond the capabilities of these conditional
8970     expressions you might want to consider writing a stored procedure
8971     in a more expressive programming language.
8972    </para>
8973   </tip>
8974
8975   <sect2>
8976    <title><literal>CASE</></title>
8977
8978   <para>
8979    The <acronym>SQL</acronym> <token>CASE</token> expression is a
8980    generic conditional expression, similar to if/else statements in
8981    other languages:
8982
8983 <synopsis>
8984 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
8985      <optional>WHEN ...</optional>
8986      <optional>ELSE <replaceable>result</replaceable></optional>
8987 END
8988 </synopsis>
8989
8990    <token>CASE</token> clauses can be used wherever
8991    an expression is valid.  <replaceable>condition</replaceable> is an
8992    expression that returns a <type>boolean</type> result.  If the result is true
8993    then the value of the <token>CASE</token> expression is the
8994    <replaceable>result</replaceable> that follows the condition.  If the result is false any
8995    subsequent <token>WHEN</token> clauses are searched in the same
8996    manner.  If no <token>WHEN</token>
8997    <replaceable>condition</replaceable> is true then the value of the
8998    case expression is the <replaceable>result</replaceable> in the
8999    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
9000    omitted and no condition matches, the result is null.
9001   </para>
9002
9003    <para>
9004     An example:
9005 <screen>
9006 SELECT * FROM test;
9007
9008  a
9009 ---
9010  1
9011  2
9012  3
9013
9014
9015 SELECT a,
9016        CASE WHEN a=1 THEN 'one'
9017             WHEN a=2 THEN 'two'
9018             ELSE 'other'
9019        END
9020     FROM test;
9021
9022  a | case
9023 ---+-------
9024  1 | one
9025  2 | two
9026  3 | other
9027 </screen>
9028    </para>
9029
9030   <para>
9031    The data types of all the <replaceable>result</replaceable>
9032    expressions must be convertible to a single output type.
9033    See <xref linkend="typeconv-union-case"> for more detail.
9034   </para>
9035
9036   <para>
9037    The following <quote>simple</quote> <token>CASE</token> expression is a
9038    specialized variant of the general form above:
9039
9040 <synopsis>
9041 CASE <replaceable>expression</replaceable>
9042     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
9043     <optional>WHEN ...</optional>
9044     <optional>ELSE <replaceable>result</replaceable></optional>
9045 END
9046 </synopsis>
9047
9048    The
9049    <replaceable>expression</replaceable> is computed and compared to
9050    all the <replaceable>value</replaceable> specifications in the
9051    <token>WHEN</token> clauses until one is found that is equal.  If
9052    no match is found, the <replaceable>result</replaceable> in the
9053    <token>ELSE</token> clause (or a null value) is returned.  This is similar
9054    to the <function>switch</function> statement in C.
9055   </para>
9056
9057    <para>
9058     The example above can be written using the simple
9059     <token>CASE</token> syntax:
9060 <screen>
9061 SELECT a,
9062        CASE a WHEN 1 THEN 'one'
9063               WHEN 2 THEN 'two'
9064               ELSE 'other'
9065        END
9066     FROM test;
9067
9068  a | case
9069 ---+-------
9070  1 | one
9071  2 | two
9072  3 | other
9073 </screen>
9074    </para>
9075
9076    <para>
9077     A <token>CASE</token> expression does not evaluate any subexpressions
9078     that are not needed to determine the result.  For example, this is a
9079     possible way of avoiding a division-by-zero failure:
9080 <programlisting>
9081 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
9082 </programlisting>
9083    </para>
9084   </sect2>
9085
9086   <sect2>
9087    <title><literal>COALESCE</></title>
9088
9089   <indexterm>
9090    <primary>COALESCE</primary>
9091   </indexterm>
9092
9093   <indexterm>
9094    <primary>NVL</primary>
9095   </indexterm>
9096
9097   <indexterm>
9098    <primary>IFNULL</primary>
9099   </indexterm>
9100
9101 <synopsis>
9102 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9103 </synopsis>
9104
9105   <para>
9106    The <function>COALESCE</function> function returns the first of its
9107    arguments that is not null.  Null is returned only if all arguments
9108    are null.  It is often used to substitute a default value for 
9109    null values when data is retrieved for display, for example:
9110 <programlisting>
9111 SELECT COALESCE(description, short_description, '(none)') ...
9112 </programlisting>
9113   </para>
9114
9115    <para>
9116     Like a <token>CASE</token> expression, <function>COALESCE</function> will
9117     not evaluate arguments that are not needed to determine the result;
9118     that is, arguments to the right of the first non-null argument are
9119     not evaluated.  This SQL-standard function provides capabilities similar
9120     to <function>NVL</> and <function>IFNULL</>, which are used in some other
9121     database systems.
9122    </para>
9123   </sect2>
9124
9125   <sect2>
9126    <title><literal>NULLIF</></title>
9127
9128   <indexterm>
9129    <primary>NULLIF</primary>
9130   </indexterm>
9131
9132 <synopsis>
9133 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
9134 </synopsis>
9135
9136   <para>
9137    The <function>NULLIF</function> function returns a null value if
9138    <replaceable>value1</replaceable> and <replaceable>value2</replaceable>
9139    are equal;  otherwise it returns <replaceable>value1</replaceable>.
9140    This can be used to perform the inverse operation of the
9141    <function>COALESCE</function> example given above:
9142 <programlisting>
9143 SELECT NULLIF(value, '(none)') ...
9144 </programlisting>
9145   </para>
9146   <para>
9147    If <replaceable>value1</replaceable> is <literal>(none)</>, return a null,
9148    otherwise return <replaceable>value1</replaceable>.
9149   </para>
9150
9151   </sect2>
9152
9153   <sect2>
9154    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
9155
9156   <indexterm>
9157    <primary>GREATEST</primary>
9158   </indexterm>
9159   <indexterm>
9160    <primary>LEAST</primary>
9161   </indexterm>
9162
9163 <synopsis>
9164 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9165 </synopsis>
9166 <synopsis>
9167 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9168 </synopsis>
9169
9170    <para>
9171     The <function>GREATEST</> and <function>LEAST</> functions select the
9172     largest or smallest value from a list of any number of expressions.
9173     The expressions must all be convertible to a common data type, which
9174     will be the type of the result
9175     (see <xref linkend="typeconv-union-case"> for details).  NULL values
9176     in the list are ignored.  The result will be NULL only if all the
9177     expressions evaluate to NULL.
9178    </para>
9179
9180    <para>
9181     Note that <function>GREATEST</> and <function>LEAST</> are not in
9182     the SQL standard, but are a common extension.  Some other databases
9183     make them return NULL if any argument is NULL, rather than only when
9184     all are NULL.
9185    </para>
9186   </sect2>
9187  </sect1>
9188
9189  <sect1 id="functions-array">
9190   <title>Array Functions and Operators</title>
9191
9192   <para>
9193    <xref linkend="array-operators-table"> shows the operators
9194    available for array types.
9195   </para>
9196
9197     <table id="array-operators-table">
9198      <title>Array Operators</title>
9199      <tgroup cols="4">
9200       <thead>
9201        <row>
9202         <entry>Operator</entry>
9203         <entry>Description</entry>
9204         <entry>Example</entry>
9205         <entry>Result</entry>
9206        </row>
9207       </thead>
9208       <tbody>
9209        <row>
9210         <entry> <literal>=</literal> </entry>
9211         <entry>equal</entry>
9212         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
9213         <entry><literal>t</literal></entry>
9214        </row>
9215
9216        <row>
9217         <entry> <literal>&lt;&gt;</literal> </entry>
9218         <entry>not equal</entry>
9219         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
9220         <entry><literal>t</literal></entry>
9221        </row>
9222
9223        <row>
9224         <entry> <literal>&lt;</literal> </entry>
9225         <entry>less than</entry>
9226         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
9227         <entry><literal>t</literal></entry>
9228        </row>
9229
9230        <row>
9231         <entry> <literal>&gt;</literal> </entry>
9232         <entry>greater than</entry>
9233         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
9234         <entry><literal>t</literal></entry>
9235        </row>
9236
9237        <row>
9238         <entry> <literal>&lt;=</literal> </entry>
9239         <entry>less than or equal</entry>
9240         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
9241         <entry><literal>t</literal></entry>
9242        </row>
9243
9244        <row>
9245         <entry> <literal>&gt;=</literal> </entry>
9246         <entry>greater than or equal</entry>
9247         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
9248         <entry><literal>t</literal></entry>
9249        </row>
9250
9251        <row>
9252         <entry> <literal>@&gt;</literal> </entry>
9253         <entry>contains</entry>
9254         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
9255         <entry><literal>t</literal></entry>
9256        </row>
9257
9258        <row>
9259         <entry> <literal>&lt;@</literal> </entry>
9260         <entry>is contained by</entry>
9261         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
9262         <entry><literal>t</literal></entry>
9263        </row>
9264
9265        <row>
9266         <entry> <literal>&amp;&amp;</literal> </entry>
9267         <entry>overlap (have elements in common)</entry>
9268         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
9269         <entry><literal>t</literal></entry>
9270        </row>
9271
9272        <row>
9273         <entry> <literal>||</literal> </entry>
9274         <entry>array-to-array concatenation</entry>
9275         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
9276         <entry><literal>{1,2,3,4,5,6}</literal></entry>
9277        </row>
9278
9279        <row>
9280         <entry> <literal>||</literal> </entry>
9281         <entry>array-to-array concatenation</entry>
9282         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
9283         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
9284        </row>
9285
9286        <row>
9287         <entry> <literal>||</literal> </entry>
9288         <entry>element-to-array concatenation</entry>
9289         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
9290         <entry><literal>{3,4,5,6}</literal></entry>
9291        </row>
9292
9293        <row>
9294         <entry> <literal>||</literal> </entry>
9295         <entry>array-to-element concatenation</entry>
9296         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
9297         <entry><literal>{4,5,6,7}</literal></entry>
9298        </row>
9299       </tbody>
9300      </tgroup>
9301     </table>
9302
9303   <para>
9304    Array comparisons compare the array contents element-by-element,
9305    using the default B-Tree comparison function for the element data type.
9306    In multidimensional arrays the elements are visited in row-major order
9307    (last subscript varies most rapidly).
9308    If the contents of two arrays are equal but the dimensionality is
9309    different, the first difference in the dimensionality information
9310    determines the sort order.  (This is a change from versions of
9311    <productname>PostgreSQL</> prior to 8.2: older versions would claim
9312    that two arrays with the same contents were equal, even if the
9313    number of dimensions or subscript ranges were different.)
9314   </para>
9315
9316   <para>
9317    See <xref linkend="arrays"> for more details about array operator
9318    behavior.
9319   </para>
9320
9321   <para>
9322    <xref linkend="array-functions-table"> shows the functions
9323    available for use with array types. See <xref linkend="arrays">
9324    for more discussion and examples of the use of these functions.
9325   </para>
9326
9327     <table id="array-functions-table">
9328      <title>Array Functions</title>
9329      <tgroup cols="5">
9330       <thead>
9331        <row>
9332         <entry>Function</entry>
9333         <entry>Return Type</entry>
9334         <entry>Description</entry>
9335         <entry>Example</entry>
9336         <entry>Result</entry>
9337        </row>
9338       </thead>
9339       <tbody>
9340        <row>
9341         <entry>
9342          <literal>
9343           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
9344          </literal>
9345         </entry>
9346         <entry><type>anyarray</type></entry>
9347         <entry>append an element to the end of an array</entry>
9348         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
9349         <entry><literal>{1,2,3}</literal></entry>
9350        </row>
9351        <row>
9352         <entry>
9353          <literal>
9354           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
9355          </literal>
9356         </entry>
9357         <entry><type>anyarray</type></entry>
9358         <entry>concatenate two arrays</entry>
9359         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
9360         <entry><literal>{1,2,3,4,5}</literal></entry>
9361        </row>
9362        <row>
9363         <entry>
9364          <literal>
9365           <function>array_dims</function>(<type>anyarray</type>)
9366          </literal>
9367         </entry>
9368         <entry><type>text</type></entry>
9369         <entry>returns a text representation of array's dimensions</entry>
9370         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9371         <entry><literal>[1:2][1:3]</literal></entry>
9372        </row>
9373        <row>
9374         <entry>
9375          <literal>
9376           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
9377           <optional>, <type>int[]</type></optional>)
9378          </literal>
9379         </entry>
9380         <entry><type>anyarray</type></entry>
9381         <entry>returns an array initialized with supplied value and
9382          dimensions, optionally with lower bounds other than 1</entry>
9383         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
9384         <entry><literal>[2:4]={7,7,7}</literal></entry>
9385        </row>
9386        <row>
9387         <entry>
9388          <literal>
9389           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
9390          </literal>
9391         </entry>
9392         <entry><type>int</type></entry>
9393         <entry>returns lower bound of the requested array dimension</entry>
9394         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
9395         <entry><literal>0</literal></entry>
9396        </row>
9397        <row>
9398         <entry>
9399          <literal>
9400           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
9401          </literal>
9402         </entry>
9403         <entry><type>anyarray</type></entry>
9404         <entry>append an element to the beginning of an array</entry>
9405         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
9406         <entry><literal>{1,2,3}</literal></entry>
9407        </row>
9408        <row>
9409         <entry>
9410          <literal>
9411           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type>)
9412          </literal>
9413         </entry>
9414         <entry><type>text</type></entry>
9415         <entry>concatenates array elements using provided delimiter</entry>
9416         <entry><literal>array_to_string(ARRAY[1, 2, 3], '~^~')</literal></entry>
9417         <entry><literal>1~^~2~^~3</literal></entry>
9418        </row>
9419        <row>
9420         <entry>
9421          <literal>
9422           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
9423          </literal>
9424         </entry>
9425         <entry><type>int</type></entry>
9426         <entry>returns upper bound of the requested array dimension</entry>
9427         <entry><literal>array_upper(ARRAY[1,2,3,4], 1)</literal></entry>
9428         <entry><literal>4</literal></entry>
9429        </row>
9430        <row>
9431         <entry>
9432          <literal>
9433           <function>string_to_array</function>(<type>text</type>, <type>text</type>)
9434          </literal>
9435         </entry>
9436         <entry><type>text[]</type></entry>
9437         <entry>splits string into array elements using provided delimiter</entry>
9438         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~')</literal></entry>
9439         <entry><literal>{xx,yy,zz}</literal></entry>
9440        </row>
9441       </tbody>
9442      </tgroup>
9443     </table>
9444   </sect1>
9445
9446  <sect1 id="functions-aggregate">
9447   <title>Aggregate Functions</title>
9448
9449   <indexterm zone="functions-aggregate">
9450    <primary>aggregate function</primary>
9451    <secondary>built-in</secondary>
9452   </indexterm>
9453
9454   <para>
9455    <firstterm>Aggregate functions</firstterm> compute a single result
9456    value from a set of input values.  The built-in aggregate functions
9457    are listed in
9458    <xref linkend="functions-aggregate-table"> and
9459    <xref linkend="functions-aggregate-statistics-table">.
9460    The special syntax considerations for aggregate
9461    functions are explained in <xref linkend="syntax-aggregates">.
9462    Consult <xref linkend="tutorial-agg"> for additional introductory
9463    information.
9464   </para>
9465
9466   <table id="functions-aggregate-table">
9467    <title>General-Purpose Aggregate Functions</title>
9468
9469    <tgroup cols="4">
9470     <thead>
9471      <row>
9472       <entry>Function</entry>
9473       <entry>Argument Type</entry>
9474       <entry>Return Type</entry>
9475       <entry>Description</entry>
9476      </row>
9477     </thead>
9478
9479     <tbody>
9480      <row>
9481       <entry>
9482        <indexterm>
9483         <primary>average</primary>
9484        </indexterm>
9485        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
9486       </entry>
9487       <entry>
9488        <type>smallint</type>, <type>int</type>,
9489        <type>bigint</type>, <type>real</type>, <type>double
9490        precision</type>, <type>numeric</type>, or <type>interval</type>
9491       </entry>
9492       <entry>
9493        <type>numeric</type> for any integer type argument,
9494        <type>double precision</type> for a floating-point argument,
9495        otherwise the same as the argument data type
9496       </entry>
9497       <entry>the average (arithmetic mean) of all input values</entry>
9498      </row>
9499
9500      <row>
9501       <entry>
9502        <indexterm>
9503         <primary>bit_and</primary>
9504        </indexterm>
9505        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
9506       </entry>
9507       <entry>
9508        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9509        <type>bit</type>
9510       </entry>
9511       <entry>
9512         same as argument data type
9513       </entry>
9514       <entry>the bitwise AND of all non-null input values, or null if none</entry>
9515      </row>
9516
9517      <row>
9518       <entry>
9519        <indexterm>
9520         <primary>bit_or</primary>
9521        </indexterm>
9522        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
9523       </entry>
9524       <entry>
9525        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9526        <type>bit</type>
9527       </entry>
9528       <entry>
9529         same as argument data type
9530       </entry>
9531       <entry>the bitwise OR of all non-null input values, or null if none</entry>
9532      </row>
9533
9534      <row>
9535       <entry>
9536        <indexterm>
9537         <primary>bool_and</primary>
9538        </indexterm>
9539        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
9540       </entry>
9541       <entry>
9542        <type>bool</type>
9543       </entry>
9544       <entry>
9545        <type>bool</type>
9546       </entry>
9547       <entry>true if all input values are true, otherwise false</entry>
9548      </row>
9549
9550      <row>
9551       <entry>
9552        <indexterm>
9553         <primary>bool_or</primary>
9554        </indexterm>
9555        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
9556       </entry>
9557       <entry>
9558        <type>bool</type>
9559       </entry>
9560       <entry>
9561        <type>bool</type>
9562       </entry>
9563       <entry>true if at least one input value is true, otherwise false</entry>
9564      </row>
9565
9566      <row>
9567       <entry><function>count(*)</function></entry>
9568       <entry></entry>
9569       <entry><type>bigint</type></entry>
9570       <entry>number of input rows</entry>
9571      </row>
9572
9573      <row>
9574       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
9575       <entry>any</entry>
9576       <entry><type>bigint</type></entry>
9577       <entry>
9578        number of input rows for which the value of <replaceable
9579        class="parameter">expression</replaceable> is not null
9580       </entry>
9581      </row>
9582
9583      <row>
9584       <entry>
9585        <indexterm>
9586         <primary>every</primary>
9587        </indexterm>
9588        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
9589       </entry>
9590       <entry>
9591        <type>bool</type>
9592       </entry>
9593       <entry>
9594        <type>bool</type>
9595       </entry>
9596       <entry>equivalent to <function>bool_and</function></entry>
9597      </row>
9598
9599      <row>
9600       <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
9601       <entry>any array, numeric, string, or date/time type</entry>
9602       <entry>same as argument type</entry>
9603       <entry>
9604        maximum value of <replaceable
9605        class="parameter">expression</replaceable> across all input
9606        values
9607       </entry>
9608      </row>
9609
9610      <row>
9611       <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
9612       <entry>any array, numeric, string, or date/time type</entry>
9613       <entry>same as argument type</entry>
9614       <entry>
9615        minimum value of <replaceable
9616        class="parameter">expression</replaceable> across all input
9617        values
9618       </entry>
9619      </row>
9620
9621      <row>
9622       <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></entry>
9623       <entry>
9624        <type>smallint</type>, <type>int</type>,
9625        <type>bigint</type>, <type>real</type>, <type>double
9626        precision</type>, <type>numeric</type>, or
9627        <type>interval</type>
9628       </entry>
9629       <entry>
9630        <type>bigint</type> for <type>smallint</type> or
9631        <type>int</type> arguments, <type>numeric</type> for
9632        <type>bigint</type> arguments, <type>double precision</type>
9633        for floating-point arguments, otherwise the same as the
9634        argument data type
9635       </entry>
9636       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
9637      </row>
9638     </tbody>
9639    </tgroup>
9640   </table>
9641
9642   <para>
9643    It should be noted that except for <function>count</function>,
9644    these functions return a null value when no rows are selected.  In
9645    particular, <function>sum</function> of no rows returns null, not
9646    zero as one might expect.  The <function>coalesce</function> function can be
9647    used to substitute zero for null when necessary.
9648   </para>
9649
9650   <note>
9651     <indexterm>
9652       <primary>ANY</primary>
9653     </indexterm>
9654     <indexterm>
9655       <primary>SOME</primary>
9656     </indexterm>
9657     <para>
9658       Boolean aggregates <function>bool_and</function> and 
9659       <function>bool_or</function> correspond to standard SQL aggregates
9660       <function>every</function> and <function>any</function> or
9661       <function>some</function>. 
9662       As for <function>any</function> and <function>some</function>, 
9663       it seems that there is an ambiguity built into the standard syntax:
9664 <programlisting>
9665 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
9666 </programlisting>
9667       Here <function>ANY</function> can be considered both as leading
9668       to a subquery or as an aggregate if the select expression returns 1 row.
9669       Thus the standard name cannot be given to these aggregates.
9670     </para>
9671   </note>
9672
9673   <note>
9674    <para>
9675     Users accustomed to working with other SQL database management
9676     systems might be surprised by the performance of the
9677     <function>count</function> aggregate when it is applied to the
9678     entire table. A query like:
9679 <programlisting>
9680 SELECT count(*) FROM sometable;
9681 </programlisting>
9682     will be executed by <productname>PostgreSQL</productname> using a
9683     sequential scan of the entire table.
9684    </para>
9685   </note>
9686
9687
9688   <para>
9689    <xref linkend="functions-aggregate-statistics-table"> shows
9690    aggregate functions typically used in statistical analysis.
9691    (These are separated out merely to avoid cluttering the listing
9692    of more-commonly-used aggregates.)  Where the description mentions
9693    <replaceable class="parameter">N</replaceable>, it means the
9694    number of input rows for which all the input expressions are non-null.
9695    In all cases, null is returned if the computation is meaningless,
9696    for example when <replaceable class="parameter">N</replaceable> is zero.
9697   </para>
9698
9699   <indexterm>
9700    <primary>statistics</primary>
9701   </indexterm>
9702   <indexterm>
9703    <primary>linear regression</primary>
9704   </indexterm>
9705
9706   <table id="functions-aggregate-statistics-table">
9707    <title>Aggregate Functions for Statistics</title>
9708
9709    <tgroup cols="4">
9710     <thead>
9711      <row>
9712       <entry>Function</entry>
9713       <entry>Argument Type</entry>
9714       <entry>Return Type</entry>
9715       <entry>Description</entry>
9716      </row>
9717     </thead>
9718
9719     <tbody>
9720
9721      <row>
9722       <entry>
9723        <indexterm>
9724         <primary>correlation</primary>
9725        </indexterm>
9726        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9727       </entry>
9728       <entry>
9729        <type>double precision</type>
9730       </entry>
9731       <entry>
9732        <type>double precision</type>
9733       </entry>
9734       <entry>correlation coefficient</entry>
9735      </row>
9736
9737      <row>
9738       <entry>
9739        <indexterm>
9740         <primary>covariance</primary>
9741         <secondary>population</secondary>
9742        </indexterm>
9743        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9744       </entry>
9745       <entry>
9746        <type>double precision</type>
9747       </entry>
9748       <entry>
9749        <type>double precision</type>
9750       </entry>
9751       <entry>population covariance</entry>
9752      </row>
9753
9754      <row>
9755       <entry>
9756        <indexterm>
9757         <primary>covariance</primary>
9758         <secondary>sample</secondary>
9759        </indexterm>
9760        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9761       </entry>
9762       <entry>
9763        <type>double precision</type>
9764       </entry>
9765       <entry>
9766        <type>double precision</type>
9767       </entry>
9768       <entry>sample covariance</entry>
9769      </row>
9770
9771      <row>
9772       <entry>
9773        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9774       </entry>
9775       <entry>
9776        <type>double precision</type>
9777       </entry>
9778       <entry>
9779        <type>double precision</type>
9780       </entry>
9781       <entry>average of the independent variable
9782       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9783      </row>
9784
9785      <row>
9786       <entry>
9787        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9788       </entry>
9789       <entry>
9790        <type>double precision</type>
9791       </entry>
9792       <entry>
9793        <type>double precision</type>
9794       </entry>
9795       <entry>average of the dependent variable
9796       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9797      </row>
9798
9799      <row>
9800       <entry>
9801        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9802       </entry>
9803       <entry>
9804        <type>double precision</type>
9805       </entry>
9806       <entry>
9807        <type>bigint</type>
9808       </entry>
9809       <entry>number of input rows in which both expressions are nonnull</entry>
9810      </row>
9811
9812      <row>
9813       <entry>
9814        <indexterm>
9815         <primary>regression intercept</primary>
9816        </indexterm>
9817        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9818       </entry>
9819       <entry>
9820        <type>double precision</type>
9821       </entry>
9822       <entry>
9823        <type>double precision</type>
9824       </entry>
9825       <entry>y-intercept of the least-squares-fit linear equation
9826       determined by the (<replaceable
9827       class="parameter">X</replaceable>, <replaceable
9828       class="parameter">Y</replaceable>) pairs</entry>
9829      </row>
9830
9831      <row>
9832       <entry>
9833        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9834       </entry>
9835       <entry>
9836        <type>double precision</type>
9837       </entry>
9838       <entry>
9839        <type>double precision</type>
9840       </entry>
9841       <entry>square of the correlation coefficient</entry>
9842      </row>
9843
9844      <row>
9845       <entry>
9846        <indexterm>
9847         <primary>regression slope</primary>
9848        </indexterm>
9849        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9850       </entry>
9851       <entry>
9852        <type>double precision</type>
9853       </entry>
9854       <entry>
9855        <type>double precision</type>
9856       </entry>
9857       <entry>slope of the least-squares-fit linear equation determined
9858       by the (<replaceable class="parameter">X</replaceable>,
9859       <replaceable class="parameter">Y</replaceable>) pairs</entry>
9860      </row>
9861
9862      <row>
9863       <entry>
9864        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9865       </entry>
9866       <entry>
9867        <type>double precision</type>
9868       </entry>
9869       <entry>
9870        <type>double precision</type>
9871       </entry>
9872       <entry><literal>sum(<replaceable
9873       class="parameter">X</replaceable>^2) - sum(<replaceable
9874       class="parameter">X</replaceable>)^2/<replaceable
9875       class="parameter">N</replaceable></literal> (<quote>sum of
9876       squares</quote> of the independent variable)</entry>
9877      </row>
9878
9879      <row>
9880       <entry>
9881        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9882       </entry>
9883       <entry>
9884        <type>double precision</type>
9885       </entry>
9886       <entry>
9887        <type>double precision</type>
9888       </entry>
9889       <entry><literal>sum(<replaceable
9890       class="parameter">X</replaceable>*<replaceable
9891       class="parameter">Y</replaceable>) - sum(<replaceable
9892       class="parameter">X</replaceable>) * sum(<replaceable
9893       class="parameter">Y</replaceable>)/<replaceable
9894       class="parameter">N</replaceable></literal> (<quote>sum of
9895       products</quote> of independent times dependent
9896       variable)</entry>
9897      </row>
9898
9899      <row>
9900       <entry>
9901        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9902       </entry>
9903       <entry>
9904        <type>double precision</type>
9905       </entry>
9906       <entry>
9907        <type>double precision</type>
9908       </entry>
9909       <entry><literal>sum(<replaceable
9910       class="parameter">Y</replaceable>^2) - sum(<replaceable
9911       class="parameter">Y</replaceable>)^2/<replaceable
9912       class="parameter">N</replaceable></literal> (<quote>sum of
9913       squares</quote> of the dependent variable)</entry>
9914      </row>
9915
9916      <row>
9917       <entry>
9918        <indexterm>
9919         <primary>standard deviation</primary>
9920        </indexterm>
9921        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
9922       </entry>
9923       <entry>
9924        <type>smallint</type>, <type>int</type>,
9925        <type>bigint</type>, <type>real</type>, <type>double
9926        precision</type>, or <type>numeric</type>
9927       </entry>
9928       <entry>
9929        <type>double precision</type> for floating-point arguments,
9930        otherwise <type>numeric</type>
9931       </entry>
9932       <entry>historical alias for <function>stddev_samp</function></entry>
9933      </row>
9934
9935      <row>
9936       <entry>
9937        <indexterm>
9938         <primary>standard deviation</primary>
9939         <secondary>population</secondary>
9940        </indexterm>
9941        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
9942       </entry>
9943       <entry>
9944        <type>smallint</type>, <type>int</type>,
9945        <type>bigint</type>, <type>real</type>, <type>double
9946        precision</type>, or <type>numeric</type>
9947       </entry>
9948       <entry>
9949        <type>double precision</type> for floating-point arguments,
9950        otherwise <type>numeric</type>
9951       </entry>
9952       <entry>population standard deviation of the input values</entry>
9953      </row>
9954
9955      <row>
9956       <entry>
9957        <indexterm>
9958         <primary>standard deviation</primary>
9959         <secondary>sample</secondary>
9960        </indexterm>
9961        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
9962       </entry>
9963       <entry>
9964        <type>smallint</type>, <type>int</type>,
9965        <type>bigint</type>, <type>real</type>, <type>double
9966        precision</type>, or <type>numeric</type>
9967       </entry>
9968       <entry>
9969        <type>double precision</type> for floating-point arguments,
9970        otherwise <type>numeric</type>
9971       </entry>
9972       <entry>sample standard deviation of the input values</entry>
9973      </row>
9974
9975      <row>
9976       <entry>
9977        <indexterm>
9978         <primary>variance</primary>
9979        </indexterm>
9980        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
9981       </entry>
9982       <entry>
9983        <type>smallint</type>, <type>int</type>,
9984        <type>bigint</type>, <type>real</type>, <type>double
9985        precision</type>, or <type>numeric</type>
9986       </entry>
9987       <entry>
9988        <type>double precision</type> for floating-point arguments,
9989        otherwise <type>numeric</type>
9990       </entry>
9991       <entry>historical alias for <function>var_samp</function></entry>
9992      </row>
9993
9994      <row>
9995       <entry>
9996        <indexterm>
9997         <primary>variance</primary>
9998         <secondary>population</secondary>
9999        </indexterm>
10000        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
10001       </entry>
10002       <entry>
10003        <type>smallint</type>, <type>int</type>,
10004        <type>bigint</type>, <type>real</type>, <type>double
10005        precision</type>, or <type>numeric</type>
10006       </entry>
10007       <entry>
10008        <type>double precision</type> for floating-point arguments,
10009        otherwise <type>numeric</type>
10010       </entry>
10011       <entry>population variance of the input values (square of the population standard deviation)</entry>
10012      </row>
10013
10014      <row>
10015       <entry>
10016        <indexterm>
10017         <primary>variance</primary>
10018         <secondary>sample</secondary>
10019        </indexterm>
10020        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
10021       </entry>
10022       <entry>
10023        <type>smallint</type>, <type>int</type>,
10024        <type>bigint</type>, <type>real</type>, <type>double
10025        precision</type>, or <type>numeric</type>
10026       </entry>
10027       <entry>
10028        <type>double precision</type> for floating-point arguments,
10029        otherwise <type>numeric</type>
10030       </entry>
10031       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
10032      </row>
10033     </tbody>
10034    </tgroup>
10035   </table>
10036
10037  </sect1>
10038
10039
10040  <sect1 id="functions-subquery">
10041   <title>Subquery Expressions</title>
10042
10043   <indexterm>
10044    <primary>EXISTS</primary>
10045   </indexterm>
10046
10047   <indexterm>
10048    <primary>IN</primary>
10049   </indexterm>
10050
10051   <indexterm>
10052    <primary>NOT IN</primary>
10053   </indexterm>
10054
10055   <indexterm>
10056    <primary>ANY</primary>
10057   </indexterm>
10058
10059   <indexterm>
10060    <primary>ALL</primary>
10061   </indexterm>
10062
10063   <indexterm>
10064    <primary>SOME</primary>
10065   </indexterm>
10066
10067   <indexterm>
10068    <primary>subquery</primary>
10069   </indexterm>
10070
10071   <para>
10072    This section describes the <acronym>SQL</acronym>-compliant subquery
10073    expressions available in <productname>PostgreSQL</productname>.
10074    All of the expression forms documented in this section return
10075    Boolean (true/false) results.
10076   </para>
10077
10078   <sect2>
10079    <title><literal>EXISTS</literal></title>
10080
10081 <synopsis>
10082 EXISTS (<replaceable>subquery</replaceable>)
10083 </synopsis>
10084
10085   <para>
10086    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
10087    or <firstterm>subquery</firstterm>.  The
10088    subquery is evaluated to determine whether it returns any rows.
10089    If it returns at least one row, the result of <token>EXISTS</token> is
10090    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token> 
10091    is <quote>false</>.
10092   </para>
10093
10094   <para>
10095    The subquery can refer to variables from the surrounding query,
10096    which will act as constants during any one evaluation of the subquery.
10097   </para>
10098
10099   <para>
10100    The subquery will generally only be executed far enough to determine
10101    whether at least one row is returned, not all the way to completion.
10102    It is unwise to write a subquery that has any side effects (such as
10103    calling sequence functions); whether the side effects occur or not
10104    might be difficult to predict.
10105   </para>
10106
10107   <para>
10108    Since the result depends only on whether any rows are returned,
10109    and not on the contents of those rows, the output list of the
10110    subquery is normally uninteresting.  A common coding convention is
10111    to write all <literal>EXISTS</> tests in the form
10112    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
10113    this rule however, such as subqueries that use <token>INTERSECT</token>.
10114   </para>
10115
10116   <para>
10117    This simple example is like an inner join on <literal>col2</>, but
10118    it produces at most one output row for each <literal>tab1</> row,
10119    even if there are multiple matching <literal>tab2</> rows:
10120 <screen>
10121 SELECT col1 FROM tab1
10122     WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
10123 </screen>
10124   </para>
10125   </sect2>
10126
10127   <sect2>
10128    <title><literal>IN</literal></title>
10129
10130 <synopsis>
10131 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
10132 </synopsis>
10133
10134   <para>
10135    The right-hand side is a parenthesized
10136    subquery, which must return exactly one column.  The left-hand expression
10137    is evaluated and compared to each row of the subquery result.
10138    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10139    The result is <quote>false</> if no equal row is found (including the special
10140    case where the subquery returns no rows).
10141   </para>
10142
10143   <para>
10144    Note that if the left-hand expression yields null, or if there are
10145    no equal right-hand values and at least one right-hand row yields
10146    null, the result of the <token>IN</token> construct will be null, not false.
10147    This is in accordance with SQL's normal rules for Boolean combinations
10148    of null values.
10149   </para>
10150
10151   <para>
10152    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10153    be evaluated completely.
10154   </para>
10155
10156 <synopsis>
10157 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
10158 </synopsis>
10159
10160   <para>
10161    The left-hand side of this form of <token>IN</token> is a row constructor,
10162    as described in <xref linkend="sql-syntax-row-constructors">.
10163    The right-hand side is a parenthesized
10164    subquery, which must return exactly as many columns as there are
10165    expressions in the left-hand row.  The left-hand expressions are
10166    evaluated and compared row-wise to each row of the subquery result.
10167    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10168    The result is <quote>false</> if no equal row is found (including the special
10169    case where the subquery returns no rows).
10170   </para>
10171
10172   <para>
10173    As usual, null values in the rows are combined per
10174    the normal rules of SQL Boolean expressions.  Two rows are considered
10175    equal if all their corresponding members are non-null and equal; the rows
10176    are unequal if any corresponding members are non-null and unequal;
10177    otherwise the result of that row comparison is unknown (null).
10178    If all the per-row results are either unequal or null, with at least one
10179    null, then the result of <token>IN</token> is null.
10180   </para>
10181   </sect2>
10182
10183   <sect2>
10184    <title><literal>NOT IN</literal></title>
10185
10186 <synopsis>
10187 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10188 </synopsis>
10189
10190   <para>
10191    The right-hand side is a parenthesized
10192    subquery, which must return exactly one column.  The left-hand expression
10193    is evaluated and compared to each row of the subquery result.
10194    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10195    are found (including the special case where the subquery returns no rows).
10196    The result is <quote>false</> if any equal row is found.
10197   </para>
10198
10199   <para>
10200    Note that if the left-hand expression yields null, or if there are
10201    no equal right-hand values and at least one right-hand row yields
10202    null, the result of the <token>NOT IN</token> construct will be null, not true.
10203    This is in accordance with SQL's normal rules for Boolean combinations
10204    of null values.
10205   </para>
10206
10207   <para>
10208    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10209    be evaluated completely.
10210   </para>
10211
10212 <synopsis>
10213 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10214 </synopsis>
10215
10216   <para>
10217    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
10218    as described in <xref linkend="sql-syntax-row-constructors">.
10219    The right-hand side is a parenthesized
10220    subquery, which must return exactly as many columns as there are
10221    expressions in the left-hand row.  The left-hand expressions are
10222    evaluated and compared row-wise to each row of the subquery result.
10223    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10224    are found (including the special case where the subquery returns no rows).
10225    The result is <quote>false</> if any equal row is found.
10226   </para>
10227
10228   <para>
10229    As usual, null values in the rows are combined per
10230    the normal rules of SQL Boolean expressions.  Two rows are considered
10231    equal if all their corresponding members are non-null and equal; the rows
10232    are unequal if any corresponding members are non-null and unequal;
10233    otherwise the result of that row comparison is unknown (null).
10234    If all the per-row results are either unequal or null, with at least one
10235    null, then the result of <token>NOT IN</token> is null.
10236   </para>
10237   </sect2>
10238
10239   <sect2>
10240    <title><literal>ANY</literal>/<literal>SOME</literal></title>
10241
10242 <synopsis>
10243 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
10244 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
10245 </synopsis>
10246
10247   <para>
10248    The right-hand side is a parenthesized
10249    subquery, which must return exactly one column.  The left-hand expression
10250    is evaluated and compared to each row of the subquery result using the
10251    given <replaceable>operator</replaceable>, which must yield a Boolean
10252    result.
10253    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10254    The result is <quote>false</> if no true result is found (including the special
10255    case where the subquery returns no rows).
10256   </para>
10257
10258   <para>
10259    <token>SOME</token> is a synonym for <token>ANY</token>.
10260    <token>IN</token> is equivalent to <literal>= ANY</literal>.
10261   </para>
10262
10263   <para>
10264    Note that if there are no successes and at least one right-hand row yields
10265    null for the operator's result, the result of the <token>ANY</token> construct
10266    will be null, not false.
10267    This is in accordance with SQL's normal rules for Boolean combinations
10268    of null values.
10269   </para>
10270
10271   <para>
10272    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10273    be evaluated completely.
10274   </para>
10275
10276 <synopsis>
10277 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
10278 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
10279 </synopsis>
10280
10281   <para>
10282    The left-hand side of this form of <token>ANY</token> is a row constructor,
10283    as described in <xref linkend="sql-syntax-row-constructors">.
10284    The right-hand side is a parenthesized
10285    subquery, which must return exactly as many columns as there are
10286    expressions in the left-hand row.  The left-hand expressions are
10287    evaluated and compared row-wise to each row of the subquery result,
10288    using the given <replaceable>operator</replaceable>.
10289    The result of <token>ANY</token> is <quote>true</> if the comparison
10290    returns true for any subquery row.
10291    The result is <quote>false</> if the comparison returns false for every
10292    subquery row (including the special case where the subquery returns no
10293    rows).
10294    The result is NULL if the comparison does not return true for any row,
10295    and it returns NULL for at least one row.
10296   </para>
10297
10298   <para>
10299    See <xref linkend="row-wise-comparison"> for details about the meaning
10300    of a row-wise comparison.
10301   </para>
10302   </sect2>
10303
10304   <sect2>
10305    <title><literal>ALL</literal></title>
10306
10307 <synopsis>
10308 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10309 </synopsis>
10310
10311   <para>
10312    The right-hand side is a parenthesized
10313    subquery, which must return exactly one column.  The left-hand expression
10314    is evaluated and compared to each row of the subquery result using the
10315    given <replaceable>operator</replaceable>, which must yield a Boolean
10316    result.
10317    The result of <token>ALL</token> is <quote>true</> if all rows yield true
10318    (including the special case where the subquery returns no rows).
10319    The result is <quote>false</> if any false result is found.
10320    The result is NULL if the comparison does not return false for any row,
10321    and it returns NULL for at least one row.
10322   </para>
10323
10324   <para>
10325    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
10326   </para>
10327
10328   <para>
10329    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10330    be evaluated completely.
10331   </para>
10332
10333 <synopsis>
10334 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10335 </synopsis>
10336
10337   <para>
10338    The left-hand side of this form of <token>ALL</token> is a row constructor,
10339    as described in <xref linkend="sql-syntax-row-constructors">.
10340    The right-hand side is a parenthesized
10341    subquery, which must return exactly as many columns as there are
10342    expressions in the left-hand row.  The left-hand expressions are
10343    evaluated and compared row-wise to each row of the subquery result,
10344    using the given <replaceable>operator</replaceable>.
10345    The result of <token>ALL</token> is <quote>true</> if the comparison
10346    returns true for all subquery rows (including the special
10347    case where the subquery returns no rows).
10348    The result is <quote>false</> if the comparison returns false for any
10349    subquery row.
10350    The result is NULL if the comparison does not return false for any
10351    subquery row, and it returns NULL for at least one row.
10352   </para>
10353
10354   <para>
10355    See <xref linkend="row-wise-comparison"> for details about the meaning
10356    of a row-wise comparison.
10357   </para>
10358   </sect2>
10359
10360   <sect2>
10361    <title>Row-wise Comparison</title>
10362
10363    <indexterm zone="functions-subquery">
10364     <primary>comparison</primary>
10365     <secondary>subquery result row</secondary>
10366    </indexterm>
10367
10368 <synopsis>
10369 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
10370 </synopsis>
10371
10372   <para>
10373    The left-hand side is a row constructor,
10374    as described in <xref linkend="sql-syntax-row-constructors">.
10375    The right-hand side is a parenthesized subquery, which must return exactly
10376    as many columns as there are expressions in the left-hand row. Furthermore,
10377    the subquery cannot return more than one row.  (If it returns zero rows,
10378    the result is taken to be null.)  The left-hand side is evaluated and
10379    compared row-wise to the single subquery result row.
10380   </para>
10381
10382   <para>
10383    See <xref linkend="row-wise-comparison"> for details about the meaning
10384    of a row-wise comparison.
10385   </para>
10386   </sect2>
10387  </sect1>
10388
10389
10390  <sect1 id="functions-comparisons">
10391   <title>Row and Array Comparisons</title>
10392
10393   <indexterm>
10394    <primary>IN</primary>
10395   </indexterm>
10396
10397   <indexterm>
10398    <primary>NOT IN</primary>
10399   </indexterm>
10400
10401   <indexterm>
10402    <primary>ANY</primary>
10403   </indexterm>
10404
10405   <indexterm>
10406    <primary>ALL</primary>
10407   </indexterm>
10408
10409   <indexterm>
10410    <primary>SOME</primary>
10411   </indexterm>
10412
10413   <indexterm>
10414    <primary>row-wise comparison</primary>
10415   </indexterm>
10416
10417   <indexterm>
10418    <primary>comparison</primary>
10419    <secondary>row-wise</secondary>
10420   </indexterm>
10421
10422   <indexterm>
10423    <primary>IS DISTINCT FROM</primary>
10424   </indexterm>
10425
10426   <indexterm>
10427    <primary>IS NOT DISTINCT FROM</primary>
10428   </indexterm>
10429
10430   <para>
10431    This section describes several specialized constructs for making
10432    multiple comparisons between groups of values.  These forms are
10433    syntactically related to the subquery forms of the previous section,
10434    but do not involve subqueries.
10435    The forms involving array subexpressions are
10436    <productname>PostgreSQL</productname> extensions; the rest are
10437    <acronym>SQL</acronym>-compliant.
10438    All of the expression forms documented in this section return
10439    Boolean (true/false) results.
10440   </para>
10441
10442   <sect2>
10443    <title><literal>IN</literal></title>
10444
10445 <synopsis>
10446 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10447 </synopsis>
10448
10449   <para>
10450    The right-hand side is a parenthesized list
10451    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
10452    result is equal to any of the right-hand expressions.  This is a shorthand
10453    notation for
10454
10455 <synopsis>
10456 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
10457 OR
10458 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
10459 OR
10460 ...
10461 </synopsis>
10462   </para>
10463
10464   <para>
10465    Note that if the left-hand expression yields null, or if there are
10466    no equal right-hand values and at least one right-hand expression yields
10467    null, the result of the <token>IN</token> construct will be null, not false.
10468    This is in accordance with SQL's normal rules for Boolean combinations
10469    of null values.
10470   </para>
10471   </sect2>
10472
10473   <sect2>
10474    <title><literal>NOT IN</literal></title>
10475
10476 <synopsis>
10477 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10478 </synopsis>
10479
10480   <para>
10481    The right-hand side is a parenthesized list
10482    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
10483    result is unequal to all of the right-hand expressions.  This is a shorthand
10484    notation for
10485
10486 <synopsis>
10487 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
10488 AND
10489 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
10490 AND
10491 ...
10492 </synopsis>
10493   </para>
10494
10495   <para>
10496    Note that if the left-hand expression yields null, or if there are
10497    no equal right-hand values and at least one right-hand expression yields
10498    null, the result of the <token>NOT IN</token> construct will be null, not true
10499    as one might naively expect.
10500    This is in accordance with SQL's normal rules for Boolean combinations
10501    of null values.
10502   </para>
10503
10504   <tip>
10505   <para>
10506    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
10507    cases.  However, null values are much more likely to trip up the novice when
10508    working with <token>NOT IN</token> than when working with <token>IN</token>.
10509    It's best to express your condition positively if possible.
10510   </para>
10511   </tip>
10512   </sect2>
10513
10514   <sect2>
10515    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
10516
10517 <synopsis>
10518 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
10519 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
10520 </synopsis>
10521
10522   <para>
10523    The right-hand side is a parenthesized expression, which must yield an
10524    array value.
10525    The left-hand expression
10526    is evaluated and compared to each element of the array using the
10527    given <replaceable>operator</replaceable>, which must yield a Boolean
10528    result.
10529    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10530    The result is <quote>false</> if no true result is found (including the special
10531    case where the array has zero elements).
10532   </para>
10533
10534   <para>
10535    If the array expression yields a null array, the result of
10536    <token>ANY</token> will be null.  If the left-hand expression yields null,
10537    the result of <token>ANY</token> is ordinarily null (though a non-strict
10538    comparison operator could possibly yield a different result).
10539    Also, if the right-hand array contains any null elements and no true
10540    comparison result is obtained, the result of <token>ANY</token>
10541    will be null, not false (again, assuming a strict comparison operator).
10542    This is in accordance with SQL's normal rules for Boolean combinations
10543    of null values.
10544   </para>
10545
10546   <para>
10547    <token>SOME</token> is a synonym for <token>ANY</token>.
10548   </para>
10549   </sect2>
10550
10551   <sect2>
10552    <title><literal>ALL</literal> (array)</title>
10553
10554 <synopsis>
10555 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
10556 </synopsis>
10557
10558   <para>
10559    The right-hand side is a parenthesized expression, which must yield an
10560    array value.
10561    The left-hand expression
10562    is evaluated and compared to each element of the array using the
10563    given <replaceable>operator</replaceable>, which must yield a Boolean
10564    result.
10565    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
10566    (including the special case where the array has zero elements).
10567    The result is <quote>false</> if any false result is found.
10568   </para>
10569
10570   <para>
10571    If the array expression yields a null array, the result of
10572    <token>ALL</token> will be null.  If the left-hand expression yields null,
10573    the result of <token>ALL</token> is ordinarily null (though a non-strict
10574    comparison operator could possibly yield a different result).
10575    Also, if the right-hand array contains any null elements and no false
10576    comparison result is obtained, the result of <token>ALL</token>
10577    will be null, not true (again, assuming a strict comparison operator).
10578    This is in accordance with SQL's normal rules for Boolean combinations
10579    of null values.
10580   </para>
10581   </sect2>
10582
10583   <sect2 id="row-wise-comparison">
10584    <title>Row-wise Comparison</title>
10585
10586 <synopsis>
10587 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
10588 </synopsis>
10589
10590   <para>
10591    Each side is a row constructor,
10592    as described in <xref linkend="sql-syntax-row-constructors">.
10593    The two row values must have the same number of fields.
10594    Each side is evaluated and they are compared row-wise.  Row comparisons
10595    are allowed when the <replaceable>operator</replaceable> is
10596    <literal>=</>,
10597    <literal>&lt;&gt;</>,
10598    <literal>&lt;</>,
10599    <literal>&lt;=</>,
10600    <literal>&gt;</> or
10601    <literal>&gt;=</>,
10602    or has semantics similar to one of these.  (To be specific, an operator
10603    can be a row comparison operator if it is a member of a B-Tree operator
10604    class, or is the negator of the <literal>=</> member of a B-Tree operator
10605    class.)
10606   </para>
10607
10608   <para>
10609    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
10610    from the others.  Two rows are considered
10611    equal if all their corresponding members are non-null and equal; the rows
10612    are unequal if any corresponding members are non-null and unequal;
10613    otherwise the result of the row comparison is unknown (null).
10614   </para>
10615
10616   <para>
10617    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
10618    <literal>&gt;=</> cases, the row elements are compared left-to-right,
10619    stopping as soon as an unequal or null pair of elements is found.
10620    If either of this pair of elements is null, the result of the
10621    row comparison is unknown (null); otherwise comparison of this pair
10622    of elements determines the result.  For example,
10623    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
10624    yields true, not null, because the third pair of elements are not
10625    considered.
10626   </para>
10627
10628   <note>
10629    <para>
10630     Prior to <productname>PostgreSQL</productname> 8.2, the
10631     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
10632     cases were not handled per SQL specification.  A comparison like
10633     <literal>ROW(a,b) &lt; ROW(c,d)</>
10634     was implemented as
10635     <literal>a &lt; c AND b &lt; d</>
10636     whereas the correct behavior is equivalent to
10637     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
10638    </para>
10639   </note>
10640
10641 <synopsis>
10642 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
10643 </synopsis>
10644
10645   <para>
10646    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
10647    but it does not yield null for null inputs.  Instead, any null value is
10648    considered unequal to (distinct from) any non-null value, and any two
10649    nulls are considered equal (not distinct).  Thus the result will always
10650    be either true or false, never null.
10651   </para>
10652
10653 <synopsis>
10654 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
10655 </synopsis>
10656
10657   <para>
10658    This construct is similar to a <literal>=</literal> row comparison,
10659    but it does not yield null for null inputs.  Instead, any null value is
10660    considered unequal to (distinct from) any non-null value, and any two
10661    nulls are considered equal (not distinct).  Thus the result will always
10662    be either true or false, never null.
10663   </para>
10664
10665   </sect2>
10666  </sect1>
10667
10668  <sect1 id="functions-srf">
10669   <title>Set Returning Functions</title>
10670
10671   <indexterm zone="functions-srf">
10672    <primary>set returning functions</primary>
10673    <secondary>functions</secondary>
10674   </indexterm>
10675
10676   <indexterm>
10677    <primary>generate_series</primary>
10678   </indexterm>
10679
10680   <para>
10681    This section describes functions that possibly return more than one row.
10682    Currently the only functions in this class are series generating functions,
10683    as detailed in <xref linkend="functions-srf-series"> and
10684    <xref linkend="functions-srf-subscripts">.
10685   </para>
10686
10687   <table id="functions-srf-series">
10688    <title>Series Generating Functions</title>
10689    <tgroup cols="4">
10690     <thead>
10691      <row>
10692       <entry>Function</entry>
10693       <entry>Argument Type</entry>
10694       <entry>Return Type</entry>
10695       <entry>Description</entry>
10696      </row>
10697     </thead>
10698
10699     <tbody>
10700      <row>
10701       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>)</literal></entry>
10702       <entry><type>int</type> or <type>bigint</type></entry>
10703       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
10704       <entry>
10705        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
10706        with a step size of one
10707       </entry>
10708      </row>
10709
10710      <row>
10711       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</literal></entry>
10712       <entry><type>int</type> or <type>bigint</type></entry>
10713       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
10714       <entry>
10715        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
10716        with a step size of <parameter>step</parameter>
10717       </entry>
10718      </row>
10719
10720      <row>
10721       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</literal></entry>
10722       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
10723       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
10724       <entry>
10725        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
10726        with a step size of <parameter>step</parameter>
10727       </entry>
10728      </row>
10729
10730     </tbody>
10731    </tgroup>
10732   </table>
10733
10734   <para>
10735    When <parameter>step</parameter> is positive, zero rows are returned if
10736    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
10737    Conversely, when <parameter>step</parameter> is negative, zero rows are
10738    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
10739    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
10740    for <parameter>step</parameter> to be zero. Some examples follow:
10741 <programlisting>
10742 select * from generate_series(2,4);
10743  generate_series
10744 -----------------
10745                2
10746                3
10747                4
10748 (3 rows)
10749
10750 select * from generate_series(5,1,-2);
10751  generate_series
10752 -----------------
10753                5
10754                3
10755                1
10756 (3 rows)
10757
10758 select * from generate_series(4,3);
10759  generate_series
10760 -----------------
10761 (0 rows)
10762
10763 -- this example relies on the date-plus-integer operator
10764 select current_date + s.a as dates from generate_series(0,14,7) as s(a);
10765    dates
10766 ------------
10767  2004-02-05
10768  2004-02-12
10769  2004-02-19
10770 (3 rows)
10771
10772 select * from generate_series('2008-03-01 00:00'::timestamp,
10773                               '2008-03-04 12:00', '10 hours');
10774    generate_series   
10775 ---------------------
10776  2008-03-01 00:00:00
10777  2008-03-01 10:00:00
10778  2008-03-01 20:00:00
10779  2008-03-02 06:00:00
10780  2008-03-02 16:00:00
10781  2008-03-03 02:00:00
10782  2008-03-03 12:00:00
10783  2008-03-03 22:00:00
10784  2008-03-04 08:00:00
10785 (9 rows)
10786 </programlisting>
10787   </para>
10788
10789   <table id="functions-srf-subscripts">
10790    <title>Subscript Generating Functions</title>
10791    <tgroup cols="3">
10792     <thead>
10793      <row>
10794       <entry>Function</entry>
10795       <entry>Return Type</entry>
10796       <entry>Description</entry>
10797      </row>
10798     </thead>
10799
10800     <tbody>
10801      <row>
10802       <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</literal></entry>
10803       <entry><type>setof int</type></entry>
10804       <entry>
10805        Generate a series comprising the given array's subscripts.
10806       </entry>
10807      </row>
10808
10809      <row>
10810       <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</literal></entry>
10811       <entry><type>setof int</type></entry>
10812       <entry>
10813        Generate a series comprising the given array's subscripts. When
10814        <parameter>reverse</parameter> is true, the series is returned in
10815        reverse order.
10816       </entry>
10817      </row>
10818
10819     </tbody>
10820    </tgroup>
10821   </table>
10822
10823   <indexterm>
10824    <primary>generate_subscripts</primary>
10825   </indexterm>
10826
10827   <para>
10828    <function>generate_subscripts</> is a convenience function that generates
10829    the set of valid subscripts for the specified dimension of the given
10830    array.
10831    Zero rows are returned for arrays that do not have the requested dimension,
10832    or for NULL arrays (but valid subscripts are returned for NULL array
10833    elements).  Some examples follow:
10834 <programlisting>
10835 -- basic usage
10836 select generate_subscripts('{NULL,1,NULL,2}'::int[], 1) as s;
10837  s 
10838 ---
10839  1
10840  2
10841  3
10842  4
10843 (4 rows)
10844
10845 -- presenting an array, the subscript and the subscripted
10846 -- value requires a subquery
10847 select * from arrays;
10848          a          
10849 --------------------
10850  {-1,-2}
10851  {100,200}
10852 (2 rows)
10853
10854 select a as array, s as subscript, a[s] as value
10855 from (select generate_subscripts(a, 1) as s, a from arrays) foo;
10856    array   | subscript | value 
10857 -----------+-----------+-------
10858  {-1,-2}   |         1 |    -1
10859  {-1,-2}   |         2 |    -2
10860  {100,200} |         1 |   100
10861  {100,200} |         2 |   200
10862 (4 rows)
10863
10864 -- unnest a 2D array
10865 create or replace function unnest2(anyarray)
10866 returns setof anyelement as $$
10867 select $1[i][j] 
10868    from generate_subscripts($1,1) g1(i),
10869         generate_subscripts($1,2) g2(j);
10870 $$ language sql immutable;
10871 CREATE FUNCTION
10872 postgres=# select * from unnest2(array[[1,2],[3,4]]);
10873  unnest2 
10874 ---------
10875        1
10876        2
10877        3
10878        4
10879 (4 rows)
10880 </programlisting>
10881   </para>
10882
10883  </sect1>
10884
10885  <sect1 id="functions-info">
10886   <title>System Information Functions</title>
10887
10888   <para>
10889    <xref linkend="functions-info-session-table"> shows several
10890    functions that extract session and system information.
10891   </para>
10892
10893   <para>
10894    In addition to the functions listed in this section, there are a number of
10895    functions related to the statistics system that also provide system
10896    information. See <xref linkend="monitoring-stats-views"> for more
10897    information.
10898   </para>
10899
10900    <table id="functions-info-session-table">
10901     <title>Session Information Functions</title>
10902     <tgroup cols="3">
10903      <thead>
10904       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
10905      </thead>
10906
10907      <tbody>
10908       <row>
10909        <entry><literal><function>current_database</function>()</literal></entry>
10910        <entry><type>name</type></entry>
10911        <entry>name of current database</entry>
10912       </row>
10913
10914       <row>
10915        <entry><literal><function>current_schema</function>()</literal></entry>
10916        <entry><type>name</type></entry>
10917        <entry>name of current schema</entry>
10918       </row>
10919
10920       <row>
10921        <entry><literal><function>current_schemas</function>(<type>boolean</type>)</literal></entry>
10922        <entry><type>name[]</type></entry>
10923        <entry>names of schemas in search path optionally including implicit schemas</entry>
10924       </row>
10925
10926       <row>
10927        <entry><literal><function>current_user</function></literal></entry>
10928        <entry><type>name</type></entry>
10929        <entry>user name of current execution context</entry>
10930       </row>
10931
10932       <row>
10933        <entry><literal><function>current_query</function></literal></entry>
10934        <entry><type>text</type></entry>
10935        <entry>text of the currently executing query (might contain more than one statement)</entry>
10936       </row>  
10937
10938       <row>
10939        <!-- See also the entry for this in monitoring.sgml -->
10940        <entry><literal><function>pg_backend_pid</function>()</literal></entry>
10941        <entry><type>int</type></entry>
10942        <entry>
10943         Process ID of the server process attached to the current session
10944        </entry>
10945       </row>
10946
10947       <row>
10948        <entry><literal><function>inet_client_addr</function>()</literal></entry>
10949        <entry><type>inet</type></entry>
10950        <entry>address of the remote connection</entry>
10951       </row>
10952
10953       <row>
10954        <entry><literal><function>inet_client_port</function>()</literal></entry>
10955        <entry><type>int</type></entry>
10956        <entry>port of the remote connection</entry>
10957       </row>
10958
10959       <row>
10960        <entry><literal><function>inet_server_addr</function>()</literal></entry>
10961        <entry><type>inet</type></entry>
10962        <entry>address of the local connection</entry>
10963       </row>
10964
10965       <row>
10966        <entry><literal><function>inet_server_port</function>()</literal></entry>
10967        <entry><type>int</type></entry>
10968        <entry>port of the local connection</entry>
10969       </row>
10970
10971       <row>
10972        <entry><literal><function>pg_my_temp_schema</function>()</literal></entry>
10973        <entry><type>oid</type></entry>
10974        <entry>OID of session's temporary schema, or 0 if none</entry>
10975       </row>
10976
10977       <row>
10978        <entry><literal><function>pg_is_other_temp_schema</function>(<type>oid</type>)</literal></entry>
10979        <entry><type>boolean</type></entry>
10980        <entry>is schema another session's temporary schema?</entry>
10981       </row>
10982
10983       <row>
10984        <entry><literal><function>pg_postmaster_start_time</function>()</literal></entry>
10985        <entry><type>timestamp with time zone</type></entry>
10986        <entry>server start time</entry>
10987       </row>
10988
10989       <row>
10990        <entry><literal><function>pg_conf_load_time</function>()</literal></entry>
10991        <entry><type>timestamp with time zone</type></entry>
10992        <entry>configuration load time</entry>
10993       </row>
10994
10995       <row>
10996        <entry><literal><function>session_user</function></literal></entry>
10997        <entry><type>name</type></entry>
10998        <entry>session user name</entry>
10999       </row>
11000
11001       <row>
11002        <entry><literal><function>user</function></literal></entry>
11003        <entry><type>name</type></entry>
11004        <entry>equivalent to <function>current_user</function></entry>
11005       </row>
11006
11007       <row>
11008        <entry><literal><function>version</function>()</literal></entry>
11009        <entry><type>text</type></entry>
11010        <entry><productname>PostgreSQL</> version information</entry>
11011       </row>
11012      </tbody>
11013     </tgroup>
11014    </table>
11015
11016    <indexterm>
11017     <primary>user</primary>
11018     <secondary>current</secondary>
11019    </indexterm>
11020
11021    <indexterm>
11022     <primary>schema</primary>
11023     <secondary>current</secondary>
11024    </indexterm>
11025
11026    <indexterm>
11027     <primary>search path</primary>
11028     <secondary>current</secondary>
11029    </indexterm>
11030
11031    <indexterm>
11032     <primary>current_database</primary>
11033    </indexterm>
11034
11035    <indexterm>
11036     <primary>current_schema</primary>
11037    </indexterm>
11038
11039    <indexterm>
11040     <primary>current_user</primary>
11041    </indexterm>
11042
11043    <para>
11044     The <function>session_user</function> is normally the user who initiated
11045     the current database connection; but superusers can change this setting
11046     with <xref linkend="sql-set-session-authorization" endterm="sql-set-session-authorization-title">.
11047     The <function>current_user</function> is the user identifier
11048     that is applicable for permission checking. Normally, it is equal
11049     to the session user, but it can be changed with
11050     <xref linkend="sql-set-role" endterm="sql-set-role-title">.
11051     It also changes during the execution of
11052     functions with the attribute <literal>SECURITY DEFINER</literal>.
11053     In Unix parlance, the session user is the <quote>real user</quote> and
11054     the current user is the <quote>effective user</quote>.
11055    </para>
11056
11057    <note>
11058     <para>
11059      <function>current_user</function>, <function>session_user</function>, and
11060      <function>user</function> have special syntactic status in <acronym>SQL</acronym>:
11061      they must be called without trailing parentheses.
11062     </para>
11063    </note>
11064
11065    <para>
11066     <function>current_schema</function> returns the name of the schema that is
11067     at the front of the search path (or a null value if the search path is
11068     empty).  This is the schema that will be used for any tables or
11069     other named objects that are created without specifying a target schema.
11070     <function>current_schemas(boolean)</function> returns an array of the names of all
11071     schemas presently in the search path.  The Boolean option determines whether or not
11072     implicitly included system schemas such as <literal>pg_catalog</> are included in the search 
11073     path returned.
11074    </para>
11075
11076    <note>
11077     <para>
11078      The search path can be altered at run time.  The command is:
11079 <programlisting>
11080 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
11081 </programlisting>
11082     </para>
11083    </note>
11084
11085    <indexterm>
11086     <primary>inet_client_addr</primary>
11087    </indexterm>
11088
11089    <indexterm>
11090     <primary>inet_client_port</primary>
11091    </indexterm>
11092
11093    <indexterm>
11094     <primary>inet_server_addr</primary>
11095    </indexterm>
11096
11097    <indexterm>
11098     <primary>inet_server_port</primary>
11099    </indexterm>
11100
11101    <para>
11102      <function>inet_client_addr</function> returns the IP address of the
11103      current client, and <function>inet_client_port</function> returns the
11104      port number.
11105      <function>inet_server_addr</function> returns the IP address on which
11106      the server accepted the current connection, and
11107      <function>inet_server_port</function> returns the port number.
11108      All these functions return NULL if the current connection is via a
11109      Unix-domain socket.
11110    </para>
11111
11112    <indexterm>
11113     <primary>pg_my_temp_schema</primary>
11114    </indexterm>
11115
11116    <indexterm>
11117     <primary>pg_is_other_temp_schema</primary>
11118    </indexterm>
11119
11120    <para>
11121     <function>pg_my_temp_schema</function> returns the OID of the current
11122     session's temporary schema, or 0 if it has none (because it has not
11123     created any temporary tables).
11124     <function>pg_is_other_temp_schema</function> returns true if the
11125     given OID is the OID of any other session's temporary schema.
11126     (This can be useful, for example, to exclude other sessions' temporary
11127     tables from a catalog display.)
11128    </para>
11129
11130    <indexterm>
11131     <primary>pg_postmaster_start_time</primary>
11132    </indexterm>
11133
11134    <para>
11135     <function>pg_postmaster_start_time</function> returns the
11136     <type>timestamp with time zone</type> when the
11137     server started.
11138    </para>
11139
11140    <indexterm>
11141     <primary>pg_conf_load_time</primary>
11142    </indexterm>
11143
11144    <para>
11145     <function>pg_conf_load_time</function> returns the
11146     <type>timestamp with time zone</type> when the
11147     server configuration files were last loaded.
11148     (If the current session was alive at the time, this will be the time
11149     when the session itself re-read the configuration files, so the
11150     reading will vary a little in different sessions.  Otherwise it is
11151     the time when the postmaster process re-read the configuration files.)
11152    </para>
11153
11154    <indexterm>
11155     <primary>version</primary>
11156    </indexterm>
11157
11158    <para>
11159     <function>version</function> returns a string describing the
11160     <productname>PostgreSQL</productname> server's version.
11161    </para>
11162
11163   <indexterm>
11164    <primary>privilege</primary>
11165    <secondary>querying</secondary>
11166   </indexterm>
11167
11168   <para>
11169    <xref linkend="functions-info-access-table"> lists functions that
11170    allow the user to query object access privileges programmatically.
11171    See <xref linkend="ddl-priv"> for more information about
11172    privileges.
11173   </para>
11174
11175    <table id="functions-info-access-table">
11176     <title>Access Privilege Inquiry Functions</title>
11177     <tgroup cols="3">
11178      <thead>
11179       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11180      </thead>
11181
11182      <tbody>
11183       <row>
11184        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
11185                                   <parameter>database</parameter>,
11186                                   <parameter>privilege</parameter>)</literal>
11187        </entry>
11188        <entry><type>boolean</type></entry>
11189        <entry>does user have privilege for database</entry>
11190       </row>
11191       <row>
11192        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
11193                                   <parameter>privilege</parameter>)</literal>
11194        </entry>
11195        <entry><type>boolean</type></entry>
11196        <entry>does current user have privilege for database</entry>
11197       </row>
11198       <row>
11199        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
11200                                   <parameter>function</parameter>,
11201                                   <parameter>privilege</parameter>)</literal>
11202        </entry>
11203        <entry><type>boolean</type></entry>
11204        <entry>does user have privilege for function</entry>
11205       </row>
11206       <row>
11207        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
11208                                   <parameter>privilege</parameter>)</literal>
11209        </entry>
11210        <entry><type>boolean</type></entry>
11211        <entry>does current user have privilege for function</entry>
11212       </row>
11213       <row>
11214        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
11215                                   <parameter>language</parameter>,
11216                                   <parameter>privilege</parameter>)</literal>
11217        </entry>
11218        <entry><type>boolean</type></entry>
11219        <entry>does user have privilege for language</entry>
11220       </row>
11221       <row>
11222        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
11223                                   <parameter>privilege</parameter>)</literal>
11224        </entry>
11225        <entry><type>boolean</type></entry>
11226        <entry>does current user have privilege for language</entry>
11227       </row>
11228       <row>
11229        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
11230                                   <parameter>schema</parameter>,
11231                                   <parameter>privilege</parameter>)</literal>
11232        </entry>
11233        <entry><type>boolean</type></entry>
11234        <entry>does user have privilege for schema</entry>
11235       </row>
11236       <row>
11237        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
11238                                   <parameter>privilege</parameter>)</literal>
11239        </entry>
11240        <entry><type>boolean</type></entry>
11241        <entry>does current user have privilege for schema</entry>
11242       </row>
11243       <row>
11244        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
11245                                   <parameter>table</parameter>,
11246                                   <parameter>privilege</parameter>)</literal>
11247        </entry>
11248        <entry><type>boolean</type></entry>
11249        <entry>does user have privilege for table</entry>
11250       </row>
11251       <row>
11252        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
11253                                   <parameter>privilege</parameter>)</literal>
11254        </entry>
11255        <entry><type>boolean</type></entry>
11256        <entry>does current user have privilege for table</entry>
11257       </row>
11258       <row>
11259        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
11260                                   <parameter>tablespace</parameter>,
11261                                   <parameter>privilege</parameter>)</literal>
11262        </entry>
11263        <entry><type>boolean</type></entry>
11264        <entry>does user have privilege for tablespace</entry>
11265       </row>
11266       <row>
11267        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
11268                                   <parameter>privilege</parameter>)</literal>
11269        </entry>
11270        <entry><type>boolean</type></entry>
11271        <entry>does current user have privilege for tablespace</entry>
11272       </row>
11273       <row>
11274        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
11275                                   <parameter>role</parameter>,
11276                                   <parameter>privilege</parameter>)</literal>
11277        </entry>
11278        <entry><type>boolean</type></entry>
11279        <entry>does user have privilege for role</entry>
11280       </row>
11281       <row>
11282        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
11283                                   <parameter>privilege</parameter>)</literal>
11284        </entry>
11285        <entry><type>boolean</type></entry>
11286        <entry>does current user have privilege for role</entry>
11287       </row>
11288      </tbody>
11289     </tgroup>
11290    </table>
11291
11292    <indexterm>
11293     <primary>has_database_privilege</primary>
11294    </indexterm>
11295    <indexterm>
11296     <primary>has_function_privilege</primary>
11297    </indexterm>
11298    <indexterm>
11299     <primary>has_language_privilege</primary>
11300    </indexterm>
11301    <indexterm>
11302     <primary>has_schema_privilege</primary>
11303    </indexterm>
11304    <indexterm>
11305     <primary>has_table_privilege</primary>
11306    </indexterm>
11307    <indexterm>
11308     <primary>has_tablespace_privilege</primary>
11309    </indexterm>
11310    <indexterm>
11311     <primary>pg_has_role</primary>
11312    </indexterm>
11313
11314    <para>
11315     <function>has_database_privilege</function> checks whether a user
11316     can access a database in a particular way.  The possibilities for its
11317     arguments are analogous to <function>has_table_privilege</function>.
11318     The desired access privilege type must evaluate to
11319     <literal>CREATE</literal>,
11320     <literal>CONNECT</literal>,
11321     <literal>TEMPORARY</literal>, or
11322     <literal>TEMP</literal> (which is equivalent to
11323     <literal>TEMPORARY</literal>).
11324    </para>
11325
11326    <para>
11327     <function>has_function_privilege</function> checks whether a user
11328     can access a function in a particular way.  The possibilities for its
11329     arguments are analogous to <function>has_table_privilege</function>.
11330     When specifying a function by a text string rather than by OID,
11331     the allowed input is the same as for the <type>regprocedure</> data type
11332     (see <xref linkend="datatype-oid">).
11333     The desired access privilege type must evaluate to
11334     <literal>EXECUTE</literal>.
11335     An example is:
11336 <programlisting>
11337 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
11338 </programlisting>
11339    </para>
11340
11341    <para>
11342     <function>has_language_privilege</function> checks whether a user
11343     can access a procedural language in a particular way.  The possibilities
11344     for its arguments are analogous to <function>has_table_privilege</function>.
11345     The desired access privilege type must evaluate to
11346     <literal>USAGE</literal>.
11347    </para>
11348
11349    <para>
11350     <function>has_schema_privilege</function> checks whether a user
11351     can access a schema in a particular way.  The possibilities for its
11352     arguments are analogous to <function>has_table_privilege</function>.
11353     The desired access privilege type must evaluate to
11354     <literal>CREATE</literal> or
11355     <literal>USAGE</literal>.
11356    </para>
11357
11358    <para>
11359     <function>has_table_privilege</function> checks whether a user
11360     can access a table in a particular way.  The user can be
11361     specified by name or by OID
11362     (<literal>pg_authid.oid</literal>), or if the argument is
11363     omitted
11364     <function>current_user</function> is assumed.  The table can be specified
11365     by name or by OID.  (Thus, there are actually six variants of
11366     <function>has_table_privilege</function>, which can be distinguished by
11367     the number and types of their arguments.)  When specifying by name,
11368     the name can be schema-qualified if necessary.
11369     The desired access privilege type
11370     is specified by a text string, which must evaluate to one of the
11371     values <literal>SELECT</literal>, <literal>INSERT</literal>,
11372     <literal>UPDATE</literal>, <literal>DELETE</literal>,
11373     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.
11374     (Case of the string is not significant, however.)
11375     An example is:
11376 <programlisting>
11377 SELECT has_table_privilege('myschema.mytable', 'select');
11378 </programlisting>
11379    </para>
11380
11381    <para>
11382     <function>has_tablespace_privilege</function> checks whether a user
11383     can access a tablespace in a particular way.  The possibilities for its
11384     arguments are analogous to <function>has_table_privilege</function>.
11385     The desired access privilege type must evaluate to
11386     <literal>CREATE</literal>.
11387    </para>
11388
11389    <para>
11390     <function>pg_has_role</function> checks whether a user
11391     can access a role in a particular way.  The possibilities for its
11392     arguments are analogous to <function>has_table_privilege</function>.
11393     The desired access privilege type must evaluate to
11394     <literal>MEMBER</literal> or
11395     <literal>USAGE</literal>.
11396     <literal>MEMBER</literal> denotes direct or indirect membership in
11397     the role (that is, the right to do <command>SET ROLE</>), while
11398     <literal>USAGE</literal> denotes whether the privileges of the role
11399     are immediately available without doing <command>SET ROLE</>.
11400    </para>
11401
11402   <para>
11403    To test whether a user holds a grant option on the privilege,
11404    append <literal>WITH GRANT OPTION</literal> to the privilege key
11405    word; for example <literal>'UPDATE WITH GRANT OPTION'</literal>.
11406   </para>
11407
11408   <para>
11409    <xref linkend="functions-info-schema-table"> shows functions that
11410    determine whether a certain object is <firstterm>visible</> in the
11411    current schema search path.
11412    For example, a table is said to be visible if its
11413    containing schema is in the search path and no table of the same
11414    name appears earlier in the search path.  This is equivalent to the
11415    statement that the table can be referenced by name without explicit
11416    schema qualification.  To list the names of all visible tables:
11417 <programlisting>
11418 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
11419 </programlisting>
11420   </para>
11421
11422    <table id="functions-info-schema-table">
11423     <title>Schema Visibility Inquiry Functions</title>
11424     <tgroup cols="3">
11425      <thead>
11426       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11427      </thead>
11428
11429      <tbody>
11430       <row>
11431        <entry><literal><function>pg_conversion_is_visible</function>(<parameter>conversion_oid</parameter>)</literal>
11432        </entry>
11433        <entry><type>boolean</type></entry>
11434        <entry>is conversion visible in search path</entry>
11435       </row>
11436       <row>
11437        <entry><literal><function>pg_function_is_visible</function>(<parameter>function_oid</parameter>)</literal>
11438        </entry>
11439        <entry><type>boolean</type></entry>
11440        <entry>is function visible in search path</entry>
11441       </row>
11442       <row>
11443        <entry><literal><function>pg_operator_is_visible</function>(<parameter>operator_oid</parameter>)</literal>
11444        </entry>
11445        <entry><type>boolean</type></entry>
11446        <entry>is operator visible in search path</entry>
11447       </row>
11448       <row>
11449        <entry><literal><function>pg_opclass_is_visible</function>(<parameter>opclass_oid</parameter>)</literal>
11450        </entry>
11451        <entry><type>boolean</type></entry>
11452        <entry>is operator class visible in search path</entry>
11453       </row>
11454       <row>
11455        <entry><literal><function>pg_table_is_visible</function>(<parameter>table_oid</parameter>)</literal>
11456        </entry>
11457        <entry><type>boolean</type></entry>
11458        <entry>is table visible in search path</entry>
11459       </row>
11460       <row>
11461        <entry><literal><function>pg_ts_config_is_visible</function>(<parameter>config_oid</parameter>)</literal>
11462        </entry>
11463        <entry><type>boolean</type></entry>
11464        <entry>is text search configuration visible in search path</entry>
11465       </row>
11466       <row>
11467        <entry><literal><function>pg_ts_dict_is_visible</function>(<parameter>dict_oid</parameter>)</literal>
11468        </entry>
11469        <entry><type>boolean</type></entry>
11470        <entry>is text search dictionary visible in search path</entry>
11471       </row>
11472       <row>
11473        <entry><literal><function>pg_ts_parser_is_visible</function>(<parameter>parser_oid</parameter>)</literal>
11474        </entry>
11475        <entry><type>boolean</type></entry>
11476        <entry>is text search parser visible in search path</entry>
11477       </row>
11478       <row>
11479        <entry><literal><function>pg_ts_template_is_visible</function>(<parameter>template_oid</parameter>)</literal>
11480        </entry>
11481        <entry><type>boolean</type></entry>
11482        <entry>is text search template visible in search path</entry>
11483       </row>
11484       <row>
11485        <entry><literal><function>pg_type_is_visible</function>(<parameter>type_oid</parameter>)</literal>
11486        </entry>
11487        <entry><type>boolean</type></entry>
11488        <entry>is type (or domain) visible in search path</entry>
11489       </row>
11490      </tbody>
11491     </tgroup>
11492    </table>
11493
11494    <indexterm>
11495     <primary>pg_conversion_is_visible</primary>
11496    </indexterm>
11497    <indexterm>
11498     <primary>pg_function_is_visible</primary>
11499    </indexterm>
11500    <indexterm>
11501     <primary>pg_operator_is_visible</primary>
11502    </indexterm>
11503    <indexterm>
11504     <primary>pg_opclass_is_visible</primary>
11505    </indexterm>
11506    <indexterm>
11507     <primary>pg_table_is_visible</primary>
11508    </indexterm>
11509    <indexterm>
11510     <primary>pg_ts_config_is_visible</primary>
11511    </indexterm>
11512    <indexterm>
11513     <primary>pg_ts_dict_is_visible</primary>
11514    </indexterm>
11515    <indexterm>
11516     <primary>pg_ts_parser_is_visible</primary>
11517    </indexterm>
11518    <indexterm>
11519     <primary>pg_ts_template_is_visible</primary>
11520    </indexterm>
11521    <indexterm>
11522     <primary>pg_type_is_visible</primary>
11523    </indexterm>
11524
11525    <para>
11526     Each function performs the visibility check for one type of database
11527     object.  Note that <function>pg_table_is_visible</function> can also be used
11528     with views, indexes and sequences; <function>pg_type_is_visible</function>
11529     can also be used with domains. For functions and operators, an object in
11530     the search path is visible if there is no object of the same name
11531     <emphasis>and argument data type(s)</> earlier in the path.  For operator
11532     classes, both name and associated index access method are considered.
11533    </para>
11534
11535    <para>
11536     All these functions require object OIDs to identify the object to be
11537     checked.  If you want to test an object by name, it is convenient to use
11538     the OID alias types (<type>regclass</>, <type>regtype</>,
11539     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
11540     or <type>regdictionary</>),
11541     for example:
11542 <programlisting>
11543 SELECT pg_type_is_visible('myschema.widget'::regtype);
11544 </programlisting>
11545     Note that it would not make much sense to test an unqualified name in
11546     this way &mdash; if the name can be recognized at all, it must be visible.
11547    </para>
11548
11549    <indexterm>
11550     <primary>format_type</primary>
11551    </indexterm>
11552
11553    <indexterm>
11554     <primary>pg_get_keywords</primary>
11555    </indexterm>
11556
11557    <indexterm>
11558     <primary>pg_get_viewdef</primary>
11559    </indexterm>
11560
11561    <indexterm>
11562     <primary>pg_get_ruledef</primary>
11563    </indexterm>
11564
11565    <indexterm>
11566     <primary>pg_get_functiondef</primary>
11567    </indexterm>
11568
11569    <indexterm>
11570     <primary>pg_get_function_arguments</primary>
11571    </indexterm>
11572
11573    <indexterm>
11574     <primary>pg_get_function_result</primary>
11575    </indexterm>
11576
11577    <indexterm>
11578     <primary>pg_get_indexdef</primary>
11579    </indexterm>
11580
11581    <indexterm>
11582     <primary>pg_get_triggerdef</primary>
11583    </indexterm>
11584
11585    <indexterm>
11586     <primary>pg_get_constraintdef</primary>
11587    </indexterm>
11588
11589    <indexterm>
11590     <primary>pg_get_expr</primary>
11591    </indexterm>
11592
11593    <indexterm>
11594     <primary>pg_get_userbyid</primary>
11595    </indexterm>
11596
11597    <indexterm>
11598     <primary>pg_get_serial_sequence</primary>
11599    </indexterm>
11600
11601    <indexterm>
11602     <primary>pg_tablespace_databases</primary>
11603    </indexterm>
11604
11605   <para>
11606    <xref linkend="functions-info-catalog-table"> lists functions that
11607    extract information from the system catalogs.
11608   </para>
11609
11610    <table id="functions-info-catalog-table">
11611     <title>System Catalog Information Functions</title>
11612     <tgroup cols="3">
11613      <thead>
11614       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11615      </thead>
11616
11617      <tbody>
11618       <row>
11619        <entry><literal><function>format_type</function>(<parameter>type_oid</parameter>, <parameter>typemod</>)</literal></entry>
11620        <entry><type>text</type></entry>
11621        <entry>get SQL name of a data type</entry>
11622       </row>
11623       <row>
11624        <entry><literal><function>pg_get_keywords</function>()</literal></entry>
11625        <entry><type>setof record</type></entry>
11626        <entry>get list of SQL keywords and their categories</entry>
11627       </row>
11628       <row>
11629        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>)</literal></entry>
11630        <entry><type>text</type></entry>
11631        <entry>get definition of a constraint</entry>
11632       </row>
11633       <row>
11634        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11635        <entry><type>text</type></entry>
11636        <entry>get definition of a constraint</entry>
11637       </row>
11638       <row>
11639        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>)</literal></entry>
11640        <entry><type>text</type></entry>
11641        <entry>decompile internal form of an expression, assuming that any Vars
11642        in it refer to the relation indicated by the second parameter</entry>
11643       </row>
11644       <row>
11645        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</literal></entry>
11646        <entry><type>text</type></entry>
11647        <entry>decompile internal form of an expression, assuming that any Vars
11648        in it refer to the relation indicated by the second parameter</entry>
11649       </row>
11650       <row>
11651        <entry><literal><function>pg_get_functiondef</function>(<parameter>func_oid</parameter>)</literal></entry>
11652        <entry><type>text</type></entry>
11653        <entry>get definition of a function</entry>
11654       </row>
11655       <row>
11656        <entry><literal><function>pg_get_function_arguments</function>(<parameter>func_oid</parameter>)</literal></entry>
11657        <entry><type>text</type></entry>
11658        <entry>get argument list for function</entry>
11659       </row>
11660       <row>
11661        <entry><literal><function>pg_get_function_result</function>(<parameter>func_oid</parameter>)</literal></entry>
11662        <entry><type>text</type></entry>
11663        <entry>get <literal>RETURNS</> clause for function</entry>
11664       </row>
11665       <row>
11666        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
11667        <entry><type>text</type></entry>
11668        <entry>get <command>CREATE INDEX</> command for index</entry>
11669       </row>
11670       <row>
11671        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</literal></entry>
11672        <entry><type>text</type></entry>
11673        <entry>get <command>CREATE INDEX</> command for index,
11674        or definition of just one index column when
11675        <parameter>column_no</> is not zero</entry>
11676       </row>
11677       <row>
11678        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>)</literal></entry>
11679        <entry><type>text</type></entry>
11680        <entry>get <command>CREATE RULE</> command for rule</entry>
11681       </row>
11682       <row>
11683        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11684        <entry><type>text</type></entry>
11685        <entry>get <command>CREATE RULE</> command for rule</entry>
11686       </row>
11687       <row>
11688        <entry><literal><function>pg_get_serial_sequence</function>(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</literal></entry>
11689        <entry><type>text</type></entry>
11690        <entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
11691        uses</entry>
11692       </row>
11693       <row>
11694        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
11695        <entry><type>text</type></entry>
11696        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
11697       </row>
11698       <row>
11699        <entry><literal><function>pg_get_userbyid</function>(<parameter>roleid</parameter>)</literal></entry>
11700        <entry><type>name</type></entry>
11701        <entry>get role name with given ID</entry>
11702       </row>
11703       <row>
11704        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>)</literal></entry>
11705        <entry><type>text</type></entry>
11706        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
11707       </row>
11708       <row>
11709        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</literal></entry>
11710        <entry><type>text</type></entry>
11711        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
11712       </row>
11713       <row>
11714        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>)</literal></entry>
11715        <entry><type>text</type></entry>
11716        <entry>get underlying <command>SELECT</command> command for view</entry>
11717       </row>
11718       <row>
11719        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11720        <entry><type>text</type></entry>
11721        <entry>get underlying <command>SELECT</command> command for view</entry>
11722       </row>
11723       <row>
11724        <entry><literal><function>pg_tablespace_databases</function>(<parameter>tablespace_oid</parameter>)</literal></entry>
11725        <entry><type>setof oid</type></entry>
11726        <entry>get the set of database OIDs that have objects in the tablespace</entry>
11727       </row>
11728      </tbody>
11729     </tgroup>
11730    </table>
11731
11732   <para>
11733    <function>format_type</function> returns the SQL name of a data type that
11734    is identified by its type OID and possibly a type modifier.  Pass NULL
11735    for the type modifier if no specific modifier is known.
11736   </para>
11737
11738   <para>
11739    <function>pg_get_keywords</function> returns a set of records describing
11740    the SQL keywords recognized by the server. The <structfield>word</> column
11741    contains the keyword.  The <structfield>catcode</> column contains a
11742    category code: <literal>U</> for unreserved, <literal>C</> for column name,
11743    <literal>T</> for type or function name, or <literal>R</> for reserved.
11744    The <structfield>catdesc</> column contains a possibly-localized string
11745    describing the category.
11746   </para>
11747
11748   <para>
11749    <function>pg_get_constraintdef</function>,
11750    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
11751    and <function>pg_get_triggerdef</function>, respectively reconstruct the
11752    creating command for a constraint, index, rule, or trigger. (Note that this
11753    is a decompiled reconstruction, not the original text of the command.)
11754    <function>pg_get_expr</function> decompiles the internal form of an
11755    individual expression, such as the default value for a column.  It can be
11756    useful when examining the contents of system catalogs.
11757    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
11758    query that defines a view. Most of these functions come in two variants,
11759    one of which can optionally <quote>pretty-print</> the result.  The
11760    pretty-printed format is more readable, but the default format is more
11761    likely to be interpreted the same way by future versions of
11762    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
11763    purposes.  Passing <literal>false</> for the pretty-print parameter yields
11764    the same result as the variant that does not have the parameter at all.
11765   </para>
11766
11767   <para>
11768    <function>pg_get_functiondef</> returns a complete
11769    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
11770    <function>pg_get_function_arguments</function> returns the argument list
11771    of a function, in the form it would need to appear in within
11772    <command>CREATE FUNCTION</>.
11773    <function>pg_get_function_result</function> similarly returns the
11774    appropriate <literal>RETURNS</> clause for the function.
11775   </para>
11776
11777   <para>
11778    <function>pg_get_serial_sequence</function> returns the name of the
11779    sequence associated with a column, or NULL if no sequence is associated
11780    with the column.  The first input parameter is a table name with
11781    optional schema, and the second parameter is a column name.  Because
11782    the first parameter is potentially a schema and table, it is not treated
11783    as a double-quoted identifier, meaning it is lowercased by default,
11784    while the second parameter, being just a column name, is treated as
11785    double-quoted and has its case preserved.  The function returns a value
11786    suitably formatted for passing to the sequence functions (see <xref
11787    linkend="functions-sequence">).  This association can be modified or
11788    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
11789    probably should have been called
11790    <function>pg_get_owned_sequence</function>; its name reflects the fact
11791    that it's typically used with <type>serial</> or <type>bigserial</>
11792    columns.)
11793   </para>
11794
11795   <para>
11796    <function>pg_get_userbyid</function> extracts a role's name given
11797    its OID.
11798   </para>
11799
11800   <para>
11801    <function>pg_tablespace_databases</function> allows a tablespace to be
11802    examined. It returns the set of OIDs of databases that have objects stored
11803    in the tablespace. If this function returns any rows, the tablespace is not
11804    empty and cannot be dropped. To display the specific objects populating the
11805    tablespace, you will need to connect to the databases identified by
11806    <function>pg_tablespace_databases</function> and query their
11807    <structname>pg_class</> catalogs.
11808   </para>
11809
11810    <indexterm>
11811     <primary>col_description</primary>
11812    </indexterm>
11813
11814    <indexterm>
11815     <primary>obj_description</primary>
11816    </indexterm>
11817
11818    <indexterm>
11819     <primary>shobj_description</primary>
11820    </indexterm>
11821
11822    <indexterm>
11823     <primary>comment</primary>
11824     <secondary sortas="database objects">about database objects</secondary>
11825    </indexterm>
11826
11827    <para>
11828     The functions shown in <xref linkend="functions-info-comment-table">
11829     extract comments previously stored with the <xref linkend="sql-comment"
11830     endterm="sql-comment-title"> command.  A null value is returned if no
11831     comment could be found matching the specified parameters.
11832    </para>
11833
11834    <table id="functions-info-comment-table">
11835     <title>Comment Information Functions</title>
11836     <tgroup cols="3">
11837      <thead>
11838       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11839      </thead>
11840
11841      <tbody>
11842       <row>
11843        <entry><literal><function>col_description</function>(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</literal></entry>
11844        <entry><type>text</type></entry>
11845        <entry>get comment for a table column</entry>
11846       </row>
11847       <row>
11848        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
11849        <entry><type>text</type></entry>
11850        <entry>get comment for a database object</entry>
11851       </row>
11852       <row>
11853        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>)</literal></entry>
11854        <entry><type>text</type></entry>
11855        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
11856       </row>
11857       <row>
11858        <entry><literal><function>shobj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
11859        <entry><type>text</type></entry>
11860        <entry>get comment for a shared database object</entry>
11861       </row>
11862      </tbody>
11863     </tgroup>
11864    </table>
11865
11866    <para>
11867     <function>col_description</function> returns the comment for a table column,
11868     which is specified by the OID of its table and its column number.
11869     <function>obj_description</function> cannot be used for table columns since
11870     columns do not have OIDs of their own.
11871    </para>
11872
11873    <para>
11874     The two-parameter form of <function>obj_description</function> returns the
11875     comment for a database object specified by its OID and the name of the
11876     containing system catalog.  For example,
11877     <literal>obj_description(123456,'pg_class')</literal>
11878     would retrieve the comment for a table with OID 123456.
11879     The one-parameter form of <function>obj_description</function> requires only
11880     the object OID.  It is now deprecated since there is no guarantee that
11881     OIDs are unique across different system catalogs; therefore, the wrong
11882     comment could be returned.
11883    </para>
11884
11885    <para>
11886     <function>shobj_description</function> is used just like
11887     <function>obj_description</function> only that it is used for retrieving
11888     comments on shared objects.  Some system catalogs are global to all
11889     databases within each cluster and their descriptions are stored globally
11890     as well.
11891    </para>
11892
11893    <indexterm>
11894     <primary>txid_current</primary>
11895    </indexterm>
11896
11897    <indexterm>
11898     <primary>txid_current_snapshot</primary>
11899    </indexterm>
11900
11901    <indexterm>
11902     <primary>txid_snapshot_xmin</primary>
11903    </indexterm>
11904
11905    <indexterm>
11906     <primary>txid_snapshot_xmax</primary>
11907    </indexterm>
11908
11909    <indexterm>
11910     <primary>txid_snapshot_xip</primary>
11911    </indexterm>
11912
11913    <indexterm>
11914     <primary>txid_visible_in_snapshot</primary>
11915    </indexterm>
11916
11917    <para>
11918     The functions shown in <xref linkend="functions-txid-snapshot">
11919     export server internal transaction information to user level.  The main
11920     use of these functions is to determine which transactions were committed
11921     between two snapshots.
11922    </para>
11923
11924    <table id="functions-txid-snapshot">
11925     <title>Transaction IDs and snapshots</title>
11926     <tgroup cols="3">
11927      <thead>
11928       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11929      </thead>
11930
11931      <tbody>
11932       <row>
11933        <entry><literal><function>txid_current</function>()</literal></entry>
11934        <entry><type>bigint</type></entry>
11935        <entry>get current transaction ID</entry>
11936       </row>
11937       <row>
11938        <entry><literal><function>txid_current_snapshot</function>()</literal></entry>
11939        <entry><type>txid_snapshot</type></entry>
11940        <entry>get current snapshot</entry>
11941       </row>
11942       <row>
11943        <entry><literal><function>txid_snapshot_xmin</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
11944        <entry><type>bigint</type></entry>
11945        <entry>get xmin of snapshot</entry>
11946       </row>
11947       <row>
11948        <entry><literal><function>txid_snapshot_xmax</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
11949        <entry><type>bigint</type></entry>
11950        <entry>get xmax of snapshot</entry>
11951       </row>
11952       <row>
11953        <entry><literal><function>txid_snapshot_xip</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
11954        <entry><type>setof bigint</type></entry>
11955        <entry>get in-progress transaction IDs in snapshot</entry>
11956       </row>
11957       <row>
11958        <entry><literal><function>txid_visible_in_snapshot</function>(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</literal></entry>
11959        <entry><type>boolean</type></entry>
11960        <entry>is transaction ID visible in snapshot?</entry>
11961       </row>
11962      </tbody>
11963     </tgroup>
11964    </table>
11965
11966    <para>
11967     The internal transaction ID type (<type>xid</>) is 32 bits wide and so
11968     it wraps around every 4 billion transactions.  However, these functions
11969     export a 64-bit format that is extended with an <quote>epoch</> counter
11970     so that it will not wrap around for the life of an installation.
11971     The data type used by these functions, <type>txid_snapshot</type>,
11972     stores information about transaction ID
11973     visibility at a particular moment in time.  Its components are
11974     described in <xref linkend="functions-txid-snapshot-parts">.
11975    </para>
11976
11977    <table id="functions-txid-snapshot-parts">
11978     <title>Snapshot components</title>
11979     <tgroup cols="2">
11980      <thead>
11981       <row>
11982        <entry>Name</entry>
11983        <entry>Description</entry>
11984       </row>
11985      </thead>
11986
11987      <tbody>
11988
11989       <row>
11990        <entry><type>xmin</type></entry>
11991        <entry>
11992          Earliest transaction ID (txid) that is still active.  All earlier
11993          transactions will either be committed and visible, or rolled
11994          back and dead.
11995        </entry>
11996       </row>
11997
11998       <row>
11999        <entry><type>xmax</type></entry>
12000        <entry>
12001         First as-yet-unassigned txid.  All txids later than this one are
12002         not yet started as of the time of the snapshot, and thus invisible.
12003        </entry>
12004       </row>
12005
12006       <row>
12007        <entry><type>xip_list</type></entry>
12008        <entry>
12009         Active txids at the time of the snapshot.  The list
12010         includes only those active txids between <literal>xmin</>
12011         and <literal>xmax</>; there might be active txids higher
12012         than xmax.  A txid that is <literal>xmin &lt;= txid &lt;
12013         xmax</literal> and not in this list was already completed
12014         at the time of the snapshot, and thus either visible or
12015         dead according to its commit status.  The list does not
12016         include txids of subtransactions.
12017        </entry>
12018       </row>
12019
12020      </tbody>
12021     </tgroup>
12022    </table>
12023
12024    <para>
12025     <type>txid_snapshot</>'s textual representation is
12026     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
12027     For example <literal>10:20:10,14,15</literal> means
12028     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
12029    </para>
12030   </sect1>
12031
12032   <sect1 id="functions-admin">
12033    <title>System Administration Functions</title>
12034
12035    <para>
12036     <xref linkend="functions-admin-set-table"> shows the functions
12037     available to query and alter run-time configuration parameters.
12038    </para>
12039
12040    <table id="functions-admin-set-table">
12041     <title>Configuration Settings Functions</title>
12042     <tgroup cols="3">
12043      <thead>
12044       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12045      </thead>
12046
12047      <tbody>
12048       <row>
12049        <entry>
12050         <literal><function>current_setting</function>(<parameter>setting_name</parameter>)</literal>
12051        </entry>
12052        <entry><type>text</type></entry>
12053        <entry>current value of setting</entry>
12054       </row>
12055       <row>
12056        <entry>
12057         <literal><function>set_config(<parameter>setting_name</parameter>,
12058                              <parameter>new_value</parameter>,
12059                              <parameter>is_local</parameter>)</function></literal>
12060        </entry>
12061        <entry><type>text</type></entry>
12062        <entry>set parameter and return new value</entry>
12063       </row>
12064      </tbody>
12065     </tgroup>
12066    </table>
12067
12068    <indexterm>
12069     <primary>SET</primary>
12070    </indexterm>
12071
12072    <indexterm>
12073     <primary>SHOW</primary>
12074    </indexterm>
12075
12076    <indexterm>
12077     <primary>configuration</primary>
12078     <secondary sortas="server">of the server</secondary>
12079     <tertiary>functions</tertiary>
12080    </indexterm>
12081
12082    <para>
12083     The function <function>current_setting</function> yields the
12084     current value of the setting <parameter>setting_name</parameter>.
12085     It corresponds to the <acronym>SQL</acronym> command
12086     <command>SHOW</command>.  An example:
12087 <programlisting>
12088 SELECT current_setting('datestyle');
12089
12090  current_setting
12091 -----------------
12092  ISO, MDY
12093 (1 row)
12094 </programlisting>
12095    </para>
12096
12097    <para>
12098     <function>set_config</function> sets the parameter
12099     <parameter>setting_name</parameter> to
12100     <parameter>new_value</parameter>.  If
12101     <parameter>is_local</parameter> is <literal>true</literal>, the
12102     new value will only apply to the current transaction. If you want
12103     the new value to apply for the current session, use
12104     <literal>false</literal> instead. The function corresponds to the
12105     SQL command <command>SET</command>. An example:
12106 <programlisting>
12107 SELECT set_config('log_statement_stats', 'off', false);
12108
12109  set_config
12110 ------------
12111  off
12112 (1 row)
12113 </programlisting>
12114    </para>
12115
12116    <indexterm>
12117     <primary>pg_cancel_backend</primary>
12118    </indexterm>
12119    <indexterm>
12120     <primary>pg_terminate_backend</primary>
12121    </indexterm>
12122    <indexterm>
12123     <primary>pg_reload_conf</primary>
12124    </indexterm>
12125    <indexterm>
12126     <primary>pg_rotate_logfile</primary>
12127    </indexterm>
12128
12129    <indexterm>
12130     <primary>signal</primary>
12131     <secondary sortas="backend">backend processes</secondary>
12132    </indexterm>
12133
12134    <para>
12135     The functions shown in <xref
12136     linkend="functions-admin-signal-table"> send control signals to
12137     other server processes.  Use of these functions is restricted
12138     to superusers.
12139    </para>
12140
12141    <table id="functions-admin-signal-table">
12142     <title>Server Signalling Functions</title>
12143     <tgroup cols="3">
12144      <thead>
12145       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12146       </row>
12147      </thead>
12148
12149      <tbody>
12150       <row>
12151        <entry>
12152         <literal><function>pg_cancel_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12153         </entry>
12154        <entry><type>boolean</type></entry>
12155        <entry>Cancel a backend's current query</entry>
12156       </row>
12157       <row>
12158        <entry>
12159         <literal><function>pg_terminate_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12160         </entry>
12161        <entry><type>boolean</type></entry>
12162        <entry>Terminate a backend</entry>
12163       </row>
12164       <row>
12165        <entry>
12166         <literal><function>pg_reload_conf</function>()</literal>
12167         </entry>
12168        <entry><type>boolean</type></entry>
12169        <entry>Cause server processes to reload their configuration files</entry>
12170       </row>
12171       <row>
12172        <entry>
12173         <literal><function>pg_rotate_logfile</function>()</literal>
12174         </entry>
12175        <entry><type>boolean</type></entry>
12176        <entry>Rotate server's log file</entry>
12177       </row>
12178      </tbody>
12179     </tgroup>
12180    </table>
12181
12182    <para>
12183     Each of these functions returns <literal>true</literal> if
12184     successful and <literal>false</literal> otherwise.
12185    </para>
12186
12187    <para>
12188     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
12189     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
12190     respectively) to backend processes identified by process ID.
12191     The process ID of an active backend can be found from
12192     the <structfield>procpid</structfield> column in the
12193     <structname>pg_stat_activity</structname> view, or by listing the
12194     <command>postgres</command> processes on the server with
12195     <application>ps</>.
12196    </para>
12197
12198    <para>
12199     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
12200     to the server, causing the configuration files
12201     to be reloaded by all server processes.
12202    </para>
12203
12204    <para>
12205     <function>pg_rotate_logfile</> signals the log-file manager to switch
12206     to a new output file immediately.  This works only when the built-in
12207     log collector is running, since otherwise there is no log-file manager 
12208     subprocess.
12209    </para>
12210
12211    <indexterm>
12212     <primary>pg_start_backup</primary>
12213    </indexterm>
12214    <indexterm>
12215     <primary>pg_stop_backup</primary>
12216    </indexterm>
12217    <indexterm>
12218     <primary>pg_switch_xlog</primary>
12219    </indexterm>
12220    <indexterm>
12221     <primary>pg_current_xlog_location</primary>
12222    </indexterm>
12223    <indexterm>
12224     <primary>pg_current_xlog_insert_location</primary>
12225    </indexterm>
12226    <indexterm>
12227     <primary>pg_xlogfile_name_offset</primary>
12228    </indexterm>
12229    <indexterm>
12230     <primary>pg_xlogfile_name</primary>
12231    </indexterm>
12232    <indexterm>
12233     <primary>backup</primary>
12234    </indexterm>
12235
12236    <para>
12237     The functions shown in <xref
12238     linkend="functions-admin-backup-table"> assist in making on-line backups.
12239     Use of the first three functions is restricted to superusers.
12240    </para>
12241
12242    <table id="functions-admin-backup-table">
12243     <title>Backup Control Functions</title>
12244     <tgroup cols="3">
12245      <thead>
12246       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12247       </row>
12248      </thead>
12249
12250      <tbody>
12251       <row>
12252        <entry>
12253         <literal><function>pg_start_backup</function>(<parameter>label</> <type>text</>)</literal>
12254         </entry>
12255        <entry><type>text</type></entry>
12256        <entry>Set up for performing on-line backup</entry>
12257       </row>
12258       <row>
12259        <entry>
12260         <literal><function>pg_stop_backup</function>()</literal>
12261         </entry>
12262        <entry><type>text</type></entry>
12263        <entry>Finish performing on-line backup</entry>
12264       </row>
12265       <row>
12266        <entry>
12267         <literal><function>pg_switch_xlog</function>()</literal>
12268         </entry>
12269        <entry><type>text</type></entry>
12270        <entry>Force switch to a new transaction log file</entry>
12271       </row>
12272       <row>
12273        <entry>
12274         <literal><function>pg_current_xlog_location</function>()</literal>
12275         </entry>
12276        <entry><type>text</type></entry>
12277        <entry>Get current transaction log write location</entry>
12278       </row>
12279       <row>
12280        <entry>
12281         <literal><function>pg_current_xlog_insert_location</function>()</literal>
12282         </entry>
12283        <entry><type>text</type></entry>
12284        <entry>Get current transaction log insert location</entry>
12285       </row>
12286       <row>
12287        <entry>
12288         <literal><function>pg_xlogfile_name_offset</function>(<parameter>location</> <type>text</>)</literal>
12289         </entry>
12290        <entry><type>text</>, <type>integer</></entry>
12291        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
12292       </row>
12293       <row>
12294        <entry>
12295         <literal><function>pg_xlogfile_name</function>(<parameter>location</> <type>text</>)</literal>
12296         </entry>
12297        <entry><type>text</type></entry>
12298        <entry>Convert transaction log location string to file name</entry>
12299       </row>
12300      </tbody>
12301     </tgroup>
12302    </table>
12303
12304    <para>
12305     <function>pg_start_backup</> accepts a single parameter which is an
12306     arbitrary user-defined label for the backup.  (Typically this would be
12307     the name under which the backup dump file will be stored.)  The function
12308     writes a backup label file into the database cluster's data directory,
12309     and then returns the backup's starting transaction log location as text.  The user
12310     need not pay any attention to this result value, but it is provided in
12311     case it is of use. 
12312 <programlisting>
12313 postgres=# select pg_start_backup('label_goes_here');
12314  pg_start_backup
12315 -----------------
12316  0/D4445B8
12317 (1 row)
12318 </programlisting>
12319    </para>
12320
12321    <para>
12322     <function>pg_stop_backup</> removes the label file created by
12323     <function>pg_start_backup</>, and instead creates a backup history file in
12324     the transaction log archive area.  The history file includes the label given to
12325     <function>pg_start_backup</>, the starting and ending transaction log locations for
12326     the backup, and the starting and ending times of the backup.  The return
12327     value is the backup's ending transaction log location (which again might be of little
12328     interest).  After noting the ending location, the current transaction log insertion
12329     point is automatically advanced to the next transaction log file, so that the
12330     ending transaction log file can be archived immediately to complete the backup.
12331    </para>
12332
12333    <para>
12334     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the 
12335     current file to be archived (assuming you are using continuous archiving).
12336     The result is the ending transaction log location within the just-completed transaction log file.
12337     If there has been no transaction log activity since the last transaction log switch,
12338     <function>pg_switch_xlog</> does nothing and returns the end location
12339     of the previous transaction log file.
12340    </para>
12341
12342    <para>
12343     <function>pg_current_xlog_location</> displays the current transaction log write
12344     location in the same format used by the above functions.  Similarly,
12345     <function>pg_current_xlog_insert_location</> displays the current transaction log
12346     insertion point.  The insertion point is the <quote>logical</> end
12347     of the transaction log
12348     at any instant, while the write location is the end of what has actually
12349     been written out from the server's internal buffers.  The write location
12350     is the end of what can be examined from outside the server, and is usually
12351     what you want if you are interested in archiving partially-complete transaction log
12352     files.  The insertion point is made available primarily for server
12353     debugging purposes.  These are both read-only operations and do not
12354     require superuser permissions.
12355    </para>
12356
12357    <para>
12358     You can use <function>pg_xlogfile_name_offset</> to extract the
12359     corresponding transaction log file name and byte offset from the results of any of the
12360     above functions.  For example:
12361 <programlisting>
12362 postgres=# select * from pg_xlogfile_name_offset(pg_stop_backup());
12363         file_name         | file_offset 
12364 --------------------------+-------------
12365  00000001000000000000000D |     4039624
12366 (1 row)
12367 </programlisting>
12368     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
12369     When the given transaction log location is exactly at a transaction log file boundary, both
12370     these functions return the name of the preceding transaction log file.
12371     This is usually the desired behavior for managing transaction log archiving
12372     behavior, since the preceding file is the last one that currently
12373     needs to be archived.
12374    </para>
12375
12376    <para>
12377     For details about proper usage of these functions, see
12378     <xref linkend="continuous-archiving">.
12379    </para>
12380
12381    <para>
12382     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
12383     the actual disk space usage of database objects.
12384    </para>
12385
12386    <indexterm>
12387     <primary>pg_column_size</primary>
12388    </indexterm>
12389    <indexterm>
12390     <primary>pg_database_size</primary>
12391    </indexterm>
12392    <indexterm>
12393     <primary>pg_relation_size</primary>
12394    </indexterm>
12395    <indexterm>
12396     <primary>pg_size_pretty</primary>
12397    </indexterm>
12398    <indexterm>
12399     <primary>pg_tablespace_size</primary>
12400    </indexterm>
12401    <indexterm>
12402     <primary>pg_total_relation_size</primary>
12403    </indexterm>
12404
12405    <table id="functions-admin-dbsize">
12406     <title>Database Object Size Functions</title>
12407     <tgroup cols="3">
12408      <thead>
12409       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12410       </row>
12411      </thead>
12412
12413      <tbody>
12414       <row>
12415        <entry><function>pg_column_size</function>(<type>any</type>)</entry>
12416        <entry><type>int</type></entry>
12417        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
12418       </row>
12419       <row>
12420        <entry>
12421         <literal><function>pg_database_size</function>(<type>oid</type>)</literal>
12422         </entry>
12423        <entry><type>bigint</type></entry>
12424        <entry>Disk space used by the database with the specified OID</entry>
12425       </row>
12426       <row>
12427        <entry>
12428         <literal><function>pg_database_size</function>(<type>name</type>)</literal>
12429         </entry>
12430        <entry><type>bigint</type></entry>
12431        <entry>Disk space used by the database with the specified name</entry>
12432       </row>
12433       <row>
12434        <entry>
12435         <literal><function>pg_relation_size</function>(<type>oid</type>)</literal>
12436         </entry>
12437        <entry><type>bigint</type></entry>
12438        <entry>Disk space used by the table or index with the specified OID</entry>
12439       </row>
12440       <row>
12441        <entry>
12442         <literal><function>pg_relation_size</function>(<type>text</type>)</literal>
12443         </entry>
12444        <entry><type>bigint</type></entry>
12445        <entry>
12446         Disk space used by the table or index with the specified name.
12447         The table name can be qualified with a schema name
12448        </entry>
12449       </row>
12450       <row>
12451        <entry>
12452         <literal><function>pg_size_pretty</function>(<type>bigint</type>)</literal>
12453         </entry>
12454        <entry><type>text</type></entry>
12455        <entry>Converts a size in bytes into a human-readable format with size units</entry>
12456       </row>
12457       <row>
12458        <entry>
12459         <literal><function>pg_tablespace_size</function>(<type>oid</type>)</literal>
12460         </entry>
12461        <entry><type>bigint</type></entry>
12462        <entry>Disk space used by the tablespace with the specified OID</entry>
12463       </row>
12464       <row>
12465        <entry>
12466         <literal><function>pg_tablespace_size</function>(<type>name</type>)</literal>
12467         </entry>
12468        <entry><type>bigint</type></entry>
12469        <entry>Disk space used by the tablespace with the specified name</entry>
12470       </row>
12471       <row>
12472        <entry>
12473         <literal><function>pg_total_relation_size</function>(<type>oid</type>)</literal>
12474         </entry>
12475        <entry><type>bigint</type></entry>
12476        <entry>
12477         Total disk space used by the table with the specified OID,
12478         including indexes and toasted data
12479        </entry>
12480       </row>
12481       <row>
12482        <entry>
12483         <literal><function>pg_total_relation_size</function>(<type>text</type>)</literal>
12484         </entry>
12485        <entry><type>bigint</type></entry>
12486        <entry>
12487         Total disk space used by the table with the specified name,
12488         including indexes and toasted data.  The table name can be
12489         qualified with a schema name
12490        </entry>
12491       </row>
12492      </tbody>
12493     </tgroup>
12494    </table>
12495
12496    <para>
12497     <function>pg_column_size</> shows the space used to store any individual
12498     data value.
12499    </para>
12500
12501    <para>
12502     <function>pg_database_size</function> and <function>pg_tablespace_size</>
12503     accept the OID or name of a database or tablespace, and return the total
12504     disk space used therein.
12505    </para>
12506
12507    <para>
12508     <function>pg_relation_size</> accepts the OID or name of a table, index or
12509     toast table, and returns the size in bytes.
12510    </para>
12511
12512    <para>
12513     <function>pg_size_pretty</> can be used to format the result of one of
12514     the other functions in a human-readable way, using kB, MB, GB or TB as
12515     appropriate.
12516    </para>
12517
12518    <para>
12519     <function>pg_total_relation_size</> accepts the OID or name of a
12520     table or toast table, and returns the size in bytes of the data
12521     and all associated indexes and toast tables.
12522    </para>
12523
12524    <para>
12525     The functions shown in <xref
12526     linkend="functions-admin-genfile"> provide native file access to
12527     files on the machine hosting the server. Only files within the
12528     database cluster directory and the <varname>log_directory</> can be
12529     accessed.  Use a relative path for files within the cluster directory,
12530     and a path matching the <varname>log_directory</> configuration setting
12531     for log files.  Use of these functions is restricted to superusers.
12532    </para>
12533
12534    <table id="functions-admin-genfile">
12535     <title>Generic File Access Functions</title>
12536     <tgroup cols="3">
12537      <thead>
12538       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12539       </row>
12540      </thead>
12541
12542      <tbody>
12543       <row>
12544        <entry>
12545         <literal><function>pg_ls_dir</function>(<parameter>dirname</> <type>text</>)</literal>
12546        </entry>
12547        <entry><type>setof text</type></entry>
12548        <entry>List the contents of a directory</entry>
12549       </row>
12550       <row>
12551        <entry>
12552         <literal><function>pg_read_file</function>(<parameter>filename</> <type>text</>, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>)</literal>
12553        </entry>
12554        <entry><type>text</type></entry>
12555        <entry>Return the contents of a text file</entry>
12556       </row>
12557       <row>
12558        <entry>
12559         <literal><function>pg_stat_file</function>(<parameter>filename</> <type>text</>)</literal>
12560        </entry>
12561        <entry><type>record</type></entry>
12562        <entry>Return information about a file</entry>
12563       </row>
12564      </tbody>
12565     </tgroup>
12566    </table>
12567
12568    <indexterm>
12569     <primary>pg_ls_dir</primary>
12570    </indexterm>
12571    <para>
12572     <function>pg_ls_dir</> returns all the names in the specified
12573     directory, except the special entries <quote><literal>.</></> and
12574     <quote><literal>..</></>.
12575    </para>
12576
12577    <indexterm>
12578     <primary>pg_read_file</primary>
12579    </indexterm>
12580    <para>
12581     <function>pg_read_file</> returns part of a text file, starting
12582     at the given <parameter>offset</>, returning at most <parameter>length</>
12583     bytes (less if the end of file is reached first).  If <parameter>offset</>
12584     is negative, it is relative to the end of the file.
12585    </para>
12586
12587    <indexterm>
12588     <primary>pg_stat_file</primary>
12589    </indexterm>
12590    <para>
12591     <function>pg_stat_file</> returns a record containing the file
12592     size, last accessed time stamp, last modified time stamp,
12593     last file status change time stamp (Unix platforms only),
12594     file creation time stamp (Windows only), and a <type>boolean</type>
12595     indicating if it is a directory.  Typical usages include:
12596 <programlisting>
12597 SELECT * FROM pg_stat_file('filename');
12598 SELECT (pg_stat_file('filename')).modification;
12599 </programlisting>
12600    </para>
12601
12602    <para>
12603     The functions shown in <xref linkend="functions-advisory-locks"> manage
12604     advisory locks.  For details about proper usage of these functions, see
12605     <xref linkend="advisory-locks">.
12606    </para>
12607
12608    <table id="functions-advisory-locks">
12609     <title>Advisory Lock Functions</title>
12610     <tgroup cols="3">
12611      <thead>
12612       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12613       </row>
12614      </thead>
12615
12616      <tbody>
12617       <row>
12618        <entry>
12619         <literal><function>pg_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
12620        </entry>
12621        <entry><type>void</type></entry>
12622        <entry>Obtain exclusive advisory lock</entry>
12623       </row>
12624       <row>
12625        <entry>
12626         <literal><function>pg_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12627        </entry>
12628        <entry><type>void</type></entry>
12629        <entry>Obtain exclusive advisory lock</entry>
12630       </row>
12631
12632       <row>
12633        <entry>
12634         <literal><function>pg_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12635        </entry>
12636        <entry><type>void</type></entry>
12637        <entry>Obtain shared advisory lock</entry>
12638       </row>
12639       <row>
12640        <entry>
12641         <literal><function>pg_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12642        </entry>
12643        <entry><type>void</type></entry>
12644        <entry>Obtain shared advisory lock</entry>
12645       </row>
12646
12647       <row>
12648        <entry>
12649         <literal><function>pg_try_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
12650        </entry>
12651        <entry><type>boolean</type></entry>
12652        <entry>Obtain exclusive advisory lock if available</entry>
12653       </row>
12654       <row>
12655        <entry>
12656         <literal><function>pg_try_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12657        </entry>
12658        <entry><type>boolean</type></entry>
12659        <entry>Obtain exclusive advisory lock if available</entry>
12660       </row>
12661
12662       <row>
12663        <entry>
12664         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12665        </entry>
12666        <entry><type>boolean</type></entry>
12667        <entry>Obtain shared advisory lock if available</entry>
12668       </row>
12669       <row>
12670        <entry>
12671         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12672        </entry>
12673        <entry><type>boolean</type></entry>
12674        <entry>Obtain shared advisory lock if available</entry>
12675       </row>
12676
12677       <row>
12678        <entry>
12679         <literal><function>pg_advisory_unlock</function>(<parameter>key</> <type>bigint</>)</literal>
12680        </entry>
12681        <entry><type>boolean</type></entry>
12682        <entry>Release an exclusive advisory lock</entry>
12683       </row>
12684       <row>
12685        <entry>
12686         <literal><function>pg_advisory_unlock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12687        </entry>
12688        <entry><type>boolean</type></entry>
12689        <entry>Release an exclusive advisory lock</entry>
12690       </row>
12691
12692       <row>
12693        <entry>
12694         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12695        </entry>
12696        <entry><type>boolean</type></entry>
12697        <entry>Release a shared advisory lock</entry>
12698       </row>
12699       <row>
12700        <entry>
12701         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12702        </entry>
12703        <entry><type>boolean</type></entry>
12704        <entry>Release a shared advisory lock</entry>
12705       </row>
12706
12707       <row>
12708        <entry>
12709         <literal><function>pg_advisory_unlock_all</function>()</literal>
12710        </entry>
12711        <entry><type>void</type></entry>
12712        <entry>Release all advisory locks held by the current session</entry>
12713       </row>
12714
12715      </tbody>
12716     </tgroup>
12717    </table>
12718
12719    <indexterm>
12720     <primary>pg_advisory_lock</primary>
12721    </indexterm>
12722    <para>
12723     <function>pg_advisory_lock</> locks an application-defined resource,
12724     which can be identified either by a single 64-bit key value or two
12725     32-bit key values (note that these two key spaces do not overlap). 
12726     The key type is specified in <literal>pg_locks.objid</>.  If
12727     another session already holds a lock on the same resource, the
12728     function will wait until the resource becomes available.  The lock
12729     is exclusive.  Multiple lock requests stack, so that if the same resource
12730     is locked three times it must be also unlocked three times to be
12731     released for other sessions' use.
12732    </para>
12733
12734    <indexterm>
12735     <primary>pg_advisory_lock_shared</primary>
12736    </indexterm>
12737    <para>
12738     <function>pg_advisory_lock_shared</> works the same as
12739     <function>pg_advisory_lock</>,
12740     except the lock can be shared with other sessions requesting shared locks.
12741     Only would-be exclusive lockers are locked out.
12742    </para>
12743
12744    <indexterm>
12745     <primary>pg_try_advisory_lock</primary>
12746    </indexterm>
12747    <para>
12748     <function>pg_try_advisory_lock</> is similar to
12749     <function>pg_advisory_lock</>, except the function will not wait for the
12750     lock to become available.  It will either obtain the lock immediately and
12751     return <literal>true</>, or return <literal>false</> if the lock cannot be
12752     acquired now.
12753    </para>
12754
12755    <indexterm>
12756     <primary>pg_try_advisory_lock_shared</primary>
12757    </indexterm>
12758    <para>
12759     <function>pg_try_advisory_lock_shared</> works the same as
12760     <function>pg_try_advisory_lock</>, except it attempts to acquire
12761     shared rather than exclusive lock.
12762    </para>
12763
12764    <indexterm>
12765     <primary>pg_advisory_unlock</primary>
12766    </indexterm>
12767    <para>
12768     <function>pg_advisory_unlock</> will release a previously-acquired
12769     exclusive advisory lock.  It
12770     will return <literal>true</> if the lock is successfully released.
12771     If the lock was in fact not held, it will return <literal>false</>,
12772     and in addition, an SQL warning will be raised by the server.
12773    </para>
12774
12775    <indexterm>
12776     <primary>pg_advisory_unlock_shared</primary>
12777    </indexterm>
12778    <para>
12779     <function>pg_advisory_unlock_shared</> works the same as
12780     <function>pg_advisory_unlock</>, 
12781     except to release a shared advisory lock.
12782    </para>
12783
12784    <indexterm>
12785     <primary>pg_advisory_unlock_all</primary>
12786    </indexterm>
12787    <para>
12788     <function>pg_advisory_unlock_all</> will release all advisory locks
12789     held by the current session.  (This function is implicitly invoked
12790     at session end, even if the client disconnects ungracefully.)
12791    </para>
12792
12793   </sect1>
12794
12795 </chapter>