]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
Remove a useless backslash from a pattern-match example. Michael Toews
[postgresql] / doc / src / sgml / func.sgml
1 <!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.479 2009/05/13 21:53:41 tgl 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 list all
21    available functions and operators, respectively.
22   </para>
23
24   <para>
25    If you are concerned about portability then note that most of
26    the functions and operators described in this chapter, with the
27    exception of the most trivial arithmetic and comparison operators
28    and some explicitly marked functions, are not specified by the
29    <acronym>SQL</acronym> standard. Some of this extended functionality
30    is present in other <acronym>SQL</acronym> database management
31    systems, and in many cases this functionality is compatible and
32    consistent between the various implementations.  This chapter is also
33    not exhaustive;  additional functions appear in relevant sections of 
34    the manual.
35   </para>
36
37
38   <sect1 id="functions-logical">
39    <title>Logical Operators</title>
40
41    <indexterm zone="functions-logical">
42     <primary>operator</primary>
43     <secondary>logical</secondary>
44    </indexterm>
45
46    <indexterm>
47     <primary>Boolean</primary>
48     <secondary>operators</secondary>
49     <see>operators, logical</see>
50    </indexterm>
51
52    <para>
53     The usual logical operators are available:
54
55     <indexterm>
56      <primary>AND (operator)</primary>
57     </indexterm>
58
59     <indexterm>
60      <primary>OR (operator)</primary>
61     </indexterm>
62
63     <indexterm>
64      <primary>NOT (operator)</primary>
65     </indexterm>
66
67     <indexterm>
68      <primary>conjunction</primary>
69     </indexterm>
70
71     <indexterm>
72      <primary>disjunction</primary>
73     </indexterm>
74
75     <indexterm>
76      <primary>negation</primary>
77     </indexterm>
78
79     <simplelist>
80      <member><literal>AND</></member>
81      <member><literal>OR</></member>
82      <member><literal>NOT</></member>
83     </simplelist>
84
85     <acronym>SQL</acronym> uses a three-valued Boolean logic where the null value represents
86     <quote>unknown</quote>.  Observe the following truth tables:
87
88     <informaltable>
89      <tgroup cols="4">
90       <thead>
91        <row>
92         <entry><replaceable>a</replaceable></entry>
93         <entry><replaceable>b</replaceable></entry>
94         <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
95         <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
96        </row>
97       </thead>
98
99       <tbody>
100        <row>
101         <entry>TRUE</entry>
102         <entry>TRUE</entry>
103         <entry>TRUE</entry>
104         <entry>TRUE</entry>
105        </row>
106
107        <row>
108         <entry>TRUE</entry>
109         <entry>FALSE</entry>
110         <entry>FALSE</entry>
111         <entry>TRUE</entry>
112        </row>
113
114        <row>
115         <entry>TRUE</entry>
116         <entry>NULL</entry>
117         <entry>NULL</entry>
118         <entry>TRUE</entry>
119        </row>
120
121        <row>
122         <entry>FALSE</entry>
123         <entry>FALSE</entry>
124         <entry>FALSE</entry>
125         <entry>FALSE</entry>
126        </row>
127
128        <row>
129         <entry>FALSE</entry>
130         <entry>NULL</entry>
131         <entry>FALSE</entry>
132         <entry>NULL</entry>
133        </row>
134
135        <row>
136         <entry>NULL</entry>
137         <entry>NULL</entry>
138         <entry>NULL</entry>
139         <entry>NULL</entry>
140        </row>
141       </tbody>
142      </tgroup>
143     </informaltable>
144
145     <informaltable>
146      <tgroup cols="2">
147       <thead>
148        <row>
149         <entry><replaceable>a</replaceable></entry>
150         <entry>NOT <replaceable>a</replaceable></entry>
151        </row>
152       </thead>
153
154       <tbody>
155        <row>
156         <entry>TRUE</entry>
157         <entry>FALSE</entry>
158        </row>
159
160        <row>
161         <entry>FALSE</entry>
162         <entry>TRUE</entry>
163        </row>
164
165        <row>
166         <entry>NULL</entry>
167         <entry>NULL</entry>
168        </row>
169       </tbody>
170      </tgroup>
171     </informaltable>
172    </para>
173
174    <para>
175     The operators <literal>AND</literal> and <literal>OR</literal> are
176     commutative, that is, you can switch the left and right operand
177     without affecting the result.  But see <xref
178     linkend="syntax-express-eval"> for more information about the
179     order of evaluation of subexpressions.
180    </para>
181   </sect1>
182
183   <sect1 id="functions-comparison">
184    <title>Comparison Operators</title>
185
186    <indexterm zone="functions-comparison">
187     <primary>comparison</primary>
188     <secondary>operators</secondary>
189    </indexterm>
190
191    <para>
192     The usual comparison operators are available, shown in <xref
193     linkend="functions-comparison-table">.
194    </para>
195
196    <table id="functions-comparison-table">
197     <title>Comparison Operators</title>
198     <tgroup cols="2">
199      <thead>
200       <row>
201        <entry>Operator</entry>
202        <entry>Description</entry>
203       </row>
204      </thead>
205
206      <tbody>
207       <row>
208        <entry> <literal>&lt;</literal> </entry>
209        <entry>less than</entry>
210       </row>
211
212       <row>
213        <entry> <literal>&gt;</literal> </entry>
214        <entry>greater than</entry>
215       </row>
216
217       <row>
218        <entry> <literal>&lt;=</literal> </entry>
219        <entry>less than or equal to</entry>
220       </row>
221
222       <row>
223        <entry> <literal>&gt;=</literal> </entry>
224        <entry>greater than or equal to</entry>
225       </row>
226
227       <row>
228        <entry> <literal>=</literal> </entry>
229        <entry>equal</entry>
230       </row>
231
232       <row>
233        <entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
234        <entry>not equal</entry>
235       </row>
236      </tbody>
237     </tgroup>
238    </table>
239
240    <note>
241     <para>
242      The <literal>!=</literal> operator is converted to
243      <literal>&lt;&gt;</literal> in the parser stage.  It is not
244      possible to implement <literal>!=</literal> and
245      <literal>&lt;&gt;</literal> operators that do different things.
246     </para>
247    </note>
248
249    <para>
250     Comparison operators are available for all relevant data types.
251     All comparison operators are binary operators that
252     return values of type <type>boolean</type>; expressions like
253     <literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
254     no <literal>&lt;</literal> operator to compare a Boolean value with
255     <literal>3</literal>).
256    </para>
257
258    <para>
259     <indexterm>
260      <primary>BETWEEN</primary>
261     </indexterm>
262     In addition to the comparison operators, the special
263     <token>BETWEEN</token> construct is available:
264 <synopsis>
265 <replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
266 </synopsis>
267     is equivalent to
268 <synopsis>
269 <replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
270 </synopsis>
271     Note <token>BETWEEN</token> is inclusive in comparing the endpoint
272     values.  <literal>NOT BETWEEN</literal> does the opposite comparison:
273 <synopsis>
274 <replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
275 </synopsis>
276     is equivalent to
277 <synopsis>
278 <replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
279 </synopsis>
280     <indexterm>
281      <primary>BETWEEN SYMMETRIC</primary>
282     </indexterm>
283     <token>BETWEEN SYMMETRIC</> is the same as <literal>BETWEEN</>
284     except there is no requirement that the argument to the left of <literal>AND</> be less than
285     or equal to the argument on the right;  the proper range is automatically determined.
286    </para>
287
288    <para>
289     <indexterm>
290      <primary>IS NULL</primary>
291     </indexterm>
292     <indexterm>
293      <primary>IS NOT NULL</primary>
294     </indexterm>
295     <indexterm>
296      <primary>ISNULL</primary>
297     </indexterm>
298     <indexterm>
299      <primary>NOTNULL</primary>
300     </indexterm>
301     To check whether a value is or is not null, use the constructs:
302 <synopsis>
303 <replaceable>expression</replaceable> IS NULL
304 <replaceable>expression</replaceable> IS NOT NULL
305 </synopsis>
306     or the equivalent, but nonstandard, constructs:
307 <synopsis>
308 <replaceable>expression</replaceable> ISNULL
309 <replaceable>expression</replaceable> NOTNULL
310 </synopsis>
311     <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
312    </para>
313
314    <para>
315     Do <emphasis>not</emphasis> write
316     <literal><replaceable>expression</replaceable> = NULL</literal>
317     because <literal>NULL</> is not <quote>equal to</quote>
318     <literal>NULL</>.  (The null value represents an unknown value,
319     and it is not known whether two unknown values are equal.) This
320     behavior conforms to the SQL standard.
321    </para>
322
323   <tip>
324    <para>
325     Some applications might expect
326     <literal><replaceable>expression</replaceable> = NULL</literal>
327     returns true if <replaceable>expression</replaceable> evaluates to
328     the null value.  It is highly recommended that these applications
329     be modified to comply with the SQL standard. However, if that
330     cannot be done the <xref linkend="guc-transform-null-equals">
331     configuration variable is available. If it is enabled,
332     <productname>PostgreSQL</productname> will convert <literal>x =
333     NULL</literal> clauses to <literal>x IS NULL</literal>.
334    </para>
335   </tip>
336
337   <note>
338    <para>
339     If the <replaceable>expression</replaceable> is row-valued, then
340     <literal>IS NULL</> is true when the row expression itself is null
341     or when all the row's fields are null, while
342     <literal>IS NOT NULL</> is true when the row expression itself is non-null
343     and all the row's fields are non-null.  Because of this behavior,
344     <literal>IS NULL</> and <literal>IS NOT NULL</> do not always return
345     inverse results for row-valued expressions, i.e., a row-valued
346     expression that contains both NULL and non-null values will return false
347     for both tests.
348     This definition conforms to the SQL standard, and is a change from the
349     inconsistent behavior exhibited by <productname>PostgreSQL</productname>
350     versions prior to 8.2.
351    </para>
352   </note>
353
354    <para>
355     <indexterm>
356      <primary>IS DISTINCT FROM</primary>
357     </indexterm>
358     <indexterm>
359      <primary>IS NOT DISTINCT FROM</primary>
360     </indexterm>
361     Ordinary comparison operators yield null (signifying <quote>unknown</>)
362     when either input is null, not true or false, e.g., <literal>7 =
363     NULL</> yields null.
364     Another way to do comparisons is with the
365     <literal>IS <optional> NOT </> DISTINCT FROM</literal> construct:
366 <synopsis>
367 <replaceable>expression</replaceable> IS DISTINCT FROM <replaceable>expression</replaceable>
368 <replaceable>expression</replaceable> IS NOT DISTINCT FROM <replaceable>expression</replaceable>
369 </synopsis>
370     For non-null inputs, <literal>IS DISTINCT FROM</literal> is
371     the same as the <literal>&lt;&gt;</> operator.  However, if both
372     inputs are null it returns false, and if only one input is
373     null it returns true.  Similarly, <literal>IS NOT DISTINCT
374     FROM</literal> is identical to <literal>=</literal> for non-null
375     inputs, but it returns true when both inputs are null, and false when only
376     one input is null. Thus, these constructs effectively act as though null
377     were a normal data value, rather than <quote>unknown</>.
378    </para>
379
380    <para>
381     <indexterm>
382      <primary>IS TRUE</primary>
383     </indexterm>
384     <indexterm>
385      <primary>IS NOT TRUE</primary>
386     </indexterm>
387     <indexterm>
388      <primary>IS FALSE</primary>
389     </indexterm>
390     <indexterm>
391      <primary>IS NOT FALSE</primary>
392     </indexterm>
393     <indexterm>
394      <primary>IS UNKNOWN</primary>
395     </indexterm>
396     <indexterm>
397      <primary>IS NOT UNKNOWN</primary>
398     </indexterm>
399     Boolean values can also be tested using the constructs
400 <synopsis>
401 <replaceable>expression</replaceable> IS TRUE
402 <replaceable>expression</replaceable> IS NOT TRUE
403 <replaceable>expression</replaceable> IS FALSE
404 <replaceable>expression</replaceable> IS NOT FALSE
405 <replaceable>expression</replaceable> IS UNKNOWN
406 <replaceable>expression</replaceable> IS NOT UNKNOWN
407 </synopsis>
408     These will always return true or false, never a null value, even when the
409     operand is null.
410     A null input is treated as the logical value <quote>unknown</>.
411     Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
412     effectively the same as <literal>IS NULL</literal> and
413     <literal>IS NOT NULL</literal>, respectively, except that the input
414     expression must be of Boolean type.
415    </para>
416  
417 <!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
418    <para>
419     <indexterm>
420      <primary>IS OF</primary>
421     </indexterm>
422     <indexterm>
423      <primary>IS NOT OF</primary>
424     </indexterm>
425     It is possible to check the data type of an expression using the
426     constructs
427 <synopsis>
428 <replaceable>expression</replaceable> IS OF (typename, ...)
429 <replaceable>expression</replaceable> IS NOT OF (typename, ...)
430 </synopsis>
431     They return a boolean value based on whether the expression's data
432     type is one of the listed data types.
433    </para>
434 -->
435
436   </sect1>
437
438   <sect1 id="functions-math">
439    <title>Mathematical Functions and Operators</title>
440
441    <para>
442     Mathematical operators are provided for many
443     <productname>PostgreSQL</productname> types. For types that support
444     only limited mathematical operations 
445     (e.g., date/time types) we
446     describe the actual behavior in subsequent sections.
447    </para>
448
449    <para>
450     <xref linkend="functions-math-op-table"> shows the available mathematical operators.
451    </para>
452
453    <table id="functions-math-op-table">
454     <title>Mathematical Operators</title>
455
456     <tgroup cols="4">
457      <thead>
458       <row>
459        <entry>Operator</entry>
460        <entry>Description</entry>
461        <entry>Example</entry>
462        <entry>Result</entry>
463       </row>
464      </thead>
465
466      <tbody>
467       <row>
468        <entry> <literal>+</literal> </entry>
469        <entry>addition</entry>
470        <entry><literal>2 + 3</literal></entry>
471        <entry><literal>5</literal></entry>
472       </row>
473
474       <row>
475        <entry> <literal>-</literal> </entry>
476        <entry>subtraction</entry>
477        <entry><literal>2 - 3</literal></entry>
478        <entry><literal>-1</literal></entry>
479       </row>
480
481       <row>
482        <entry> <literal>*</literal> </entry>
483        <entry>multiplication</entry>
484        <entry><literal>2 * 3</literal></entry>
485        <entry><literal>6</literal></entry>
486       </row>
487
488       <row>
489        <entry> <literal>/</literal> </entry>
490        <entry>division (integer division truncates the result)</entry>
491        <entry><literal>4 / 2</literal></entry>
492        <entry><literal>2</literal></entry>
493       </row>
494
495       <row>
496        <entry> <literal>%</literal> </entry>
497        <entry>modulo (remainder)</entry>
498        <entry><literal>5 % 4</literal></entry>
499        <entry><literal>1</literal></entry>
500       </row>
501
502       <row>
503        <entry> <literal>^</literal> </entry>
504        <entry>exponentiation</entry>
505        <entry><literal>2.0 ^ 3.0</literal></entry>
506        <entry><literal>8</literal></entry>
507       </row>
508
509       <row>
510        <entry> <literal>|/</literal> </entry>
511        <entry>square root</entry>
512        <entry><literal>|/ 25.0</literal></entry>
513        <entry><literal>5</literal></entry>
514       </row>
515
516       <row>
517        <entry> <literal>||/</literal> </entry>
518        <entry>cube root</entry>
519        <entry><literal>||/ 27.0</literal></entry>
520        <entry><literal>3</literal></entry>
521       </row>
522
523       <row>
524        <entry> <literal>!</literal> </entry>
525        <entry>factorial</entry>
526        <entry><literal>5 !</literal></entry>
527        <entry><literal>120</literal></entry>
528       </row>
529
530       <row>
531        <entry> <literal>!!</literal> </entry>
532        <entry>factorial (prefix operator)</entry>
533        <entry><literal>!! 5</literal></entry>
534        <entry><literal>120</literal></entry>
535       </row>
536
537       <row>
538        <entry> <literal>@</literal> </entry>
539        <entry>absolute value</entry>
540        <entry><literal>@ -5.0</literal></entry>
541        <entry><literal>5</literal></entry>
542       </row>
543
544       <row>
545        <entry> <literal>&amp;</literal> </entry>
546        <entry>bitwise AND</entry>
547        <entry><literal>91 &amp; 15</literal></entry>
548        <entry><literal>11</literal></entry>
549       </row>
550
551       <row>
552        <entry> <literal>|</literal> </entry>
553        <entry>bitwise OR</entry>
554        <entry><literal>32 | 3</literal></entry>
555        <entry><literal>35</literal></entry>
556       </row>
557
558       <row>
559        <entry> <literal>#</literal> </entry>
560        <entry>bitwise XOR</entry>
561        <entry><literal>17 # 5</literal></entry>
562        <entry><literal>20</literal></entry>
563       </row>
564
565       <row>
566        <entry> <literal>~</literal> </entry>
567        <entry>bitwise NOT</entry>
568        <entry><literal>~1</literal></entry>
569        <entry><literal>-2</literal></entry>
570       </row>
571
572       <row>
573        <entry> <literal>&lt;&lt;</literal> </entry>
574        <entry>bitwise shift left</entry>
575        <entry><literal>1 &lt;&lt; 4</literal></entry>
576        <entry><literal>16</literal></entry>
577       </row>
578
579       <row>
580        <entry> <literal>&gt;&gt;</literal> </entry>
581        <entry>bitwise shift right</entry>
582        <entry><literal>8 &gt;&gt; 2</literal></entry>
583        <entry><literal>2</literal></entry>
584       </row>
585
586      </tbody>
587     </tgroup>
588    </table>
589
590    <para>
591     The bitwise operators work only on integral data types, whereas
592     the others are available for all numeric data types.  The bitwise
593     operators are also available for the bit
594     string types <type>bit</type> and <type>bit varying</type>, as
595     shown in <xref linkend="functions-bit-string-op-table">.
596    </para>
597
598   <para>
599    <xref linkend="functions-math-func-table"> shows the available
600    mathematical functions.  In the table, <literal>dp</literal>
601    indicates <type>double precision</type>.  Many of these functions
602    are provided in multiple forms with different argument types.
603    Except where noted, any given form of a function returns the same
604    data type as its argument.
605    The functions working with <type>double precision</type> data are mostly
606    implemented on top of the host system's C library; accuracy and behavior in
607    boundary cases can therefore vary depending on the host system.
608   </para>
609
610    <indexterm>
611     <primary>abs</primary>
612    </indexterm>
613    <indexterm>
614     <primary>cbrt</primary>
615    </indexterm>
616    <indexterm>
617     <primary>ceiling</primary>
618    </indexterm>
619    <indexterm>
620     <primary>degrees</primary>
621    </indexterm>
622    <indexterm>
623     <primary>div</primary>
624    </indexterm>
625    <indexterm>
626     <primary>exp</primary>
627    </indexterm>
628    <indexterm>
629     <primary>floor</primary>
630    </indexterm>
631    <indexterm>
632     <primary>ln</primary>
633    </indexterm>
634    <indexterm>
635     <primary>log</primary>
636    </indexterm>
637    <indexterm>
638     <primary>mod</primary>
639    </indexterm>
640    <indexterm>
641     <primary>pi</primary>
642    </indexterm>
643    <indexterm>
644     <primary>power</primary>
645    </indexterm>
646    <indexterm>
647     <primary>radians</primary>
648    </indexterm>
649    <indexterm>
650     <primary>random</primary>
651    </indexterm>
652    <indexterm>
653     <primary>round</primary>
654    </indexterm>
655    <indexterm>
656     <primary>setseed</primary>
657    </indexterm>
658    <indexterm>
659     <primary>sign</primary>
660    </indexterm>
661    <indexterm>
662     <primary>sqrt</primary>
663    </indexterm>
664    <indexterm>
665     <primary>trunc</primary>
666    </indexterm>
667    <indexterm>
668     <primary>width_bucket</primary>
669    </indexterm>
670
671    <table id="functions-math-func-table">
672     <title>Mathematical Functions</title>
673     <tgroup cols="5">
674      <thead>
675       <row>
676        <entry>Function</entry>
677        <entry>Return Type</entry>
678        <entry>Description</entry>
679        <entry>Example</entry>
680        <entry>Result</entry>
681       </row>
682      </thead>
683
684      <tbody>
685       <row>
686        <entry><literal><function>abs</>(<replaceable>x</replaceable>)</literal></entry>
687        <entry>(same as input)</entry>
688        <entry>absolute value</entry>
689        <entry><literal>abs(-17.4)</literal></entry>
690        <entry><literal>17.4</literal></entry>
691       </row>
692
693       <row>
694        <entry><literal><function>cbrt</function>(<type>dp</type>)</literal></entry>
695        <entry><type>dp</type></entry>
696        <entry>cube root</entry>
697        <entry><literal>cbrt(27.0)</literal></entry>
698        <entry><literal>3</literal></entry>
699       </row>
700
701       <row>
702        <entry><literal><function>ceil</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
703        <entry>(same as input)</entry>
704        <entry>smallest integer not less than argument</entry>
705        <entry><literal>ceil(-42.8)</literal></entry>
706        <entry><literal>-42</literal></entry>
707       </row>
708
709       <row>
710        <entry><literal><function>ceiling</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
711        <entry>(same as input)</entry>
712        <entry>smallest integer not less than argument (alias for <function>ceil</function>)</entry>
713        <entry><literal>ceiling(-95.3)</literal></entry>
714        <entry><literal>-95</literal></entry>
715       </row>
716
717       <row>
718        <entry><literal><function>degrees</function>(<type>dp</type>)</literal></entry>
719        <entry><type>dp</type></entry>
720        <entry>radians to degrees</entry>
721        <entry><literal>degrees(0.5)</literal></entry>
722        <entry><literal>28.6478897565412</literal></entry>
723       </row>
724
725       <row>
726        <entry><literal><function>div</function>(<parameter>y</parameter> <type>numeric</>,
727         <parameter>x</parameter> <type>numeric</>)</literal></entry>
728        <entry><type>numeric</></entry>
729        <entry>integer quotient of <parameter>y</parameter>/<parameter>x</parameter></entry>
730        <entry><literal>div(9,4)</literal></entry>
731        <entry><literal>2</literal></entry>
732       </row>
733
734       <row>
735        <entry><literal><function>exp</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
736        <entry>(same as input)</entry>
737        <entry>exponential</entry>
738        <entry><literal>exp(1.0)</literal></entry>
739        <entry><literal>2.71828182845905</literal></entry>
740       </row>
741
742       <row>
743        <entry><literal><function>floor</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
744        <entry>(same as input)</entry>
745        <entry>largest integer not greater than argument</entry>
746        <entry><literal>floor(-42.8)</literal></entry>
747        <entry><literal>-43</literal></entry>
748       </row>
749
750       <row>
751        <entry><literal><function>ln</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
752        <entry>(same as input)</entry>
753        <entry>natural logarithm</entry>
754        <entry><literal>ln(2.0)</literal></entry>
755        <entry><literal>0.693147180559945</literal></entry>
756       </row>
757
758       <row>
759        <entry><literal><function>log</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
760        <entry>(same as input)</entry>
761        <entry>base 10 logarithm</entry>
762        <entry><literal>log(100.0)</literal></entry>
763        <entry><literal>2</literal></entry>
764       </row>
765
766       <row>
767        <entry><literal><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
768         <parameter>x</parameter> <type>numeric</type>)</literal></entry>
769        <entry><type>numeric</type></entry>
770        <entry>logarithm to base <parameter>b</parameter></entry>
771        <entry><literal>log(2.0, 64.0)</literal></entry>
772        <entry><literal>6.0000000000</literal></entry>
773       </row>
774
775       <row>
776        <entry><literal><function>mod</function>(<parameter>y</parameter>,
777         <parameter>x</parameter>)</literal></entry>
778        <entry>(same as argument types)</entry>
779        <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
780        <entry><literal>mod(9,4)</literal></entry>
781        <entry><literal>1</literal></entry>
782       </row>
783
784       <row>
785        <entry><literal><function>pi</function>()</literal></entry>
786        <entry><type>dp</type></entry>
787        <entry><quote>&pi;</quote> constant</entry>
788        <entry><literal>pi()</literal></entry>
789        <entry><literal>3.14159265358979</literal></entry>
790       </row>
791
792       <row>
793        <entry><literal><function>power</function>(<parameter>a</parameter> <type>dp</type>,
794         <parameter>b</parameter> <type>dp</type>)</literal></entry>
795        <entry><type>dp</type></entry>
796        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
797        <entry><literal>power(9.0, 3.0)</literal></entry>
798        <entry><literal>729</literal></entry>
799       </row>
800
801       <row>
802        <entry><literal><function>power</function>(<parameter>a</parameter> <type>numeric</type>,
803         <parameter>b</parameter> <type>numeric</type>)</literal></entry>
804        <entry><type>numeric</type></entry>
805        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
806        <entry><literal>power(9.0, 3.0)</literal></entry>
807        <entry><literal>729</literal></entry>
808       </row>
809
810       <row>
811        <entry><literal><function>radians</function>(<type>dp</type>)</literal></entry>
812        <entry><type>dp</type></entry>
813        <entry>degrees to radians</entry>
814        <entry><literal>radians(45.0)</literal></entry>
815        <entry><literal>0.785398163397448</literal></entry>
816       </row>
817
818       <row>
819        <entry><literal><function>random</function>()</literal></entry>
820        <entry><type>dp</type></entry>
821        <entry>random value between 0.0 and 1.0, inclusive</entry>
822        <entry><literal>random()</literal></entry>
823        <entry></entry>
824       </row>
825
826       <row>
827        <entry><literal><function>round</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
828        <entry>(same as input)</entry>
829        <entry>round to nearest integer</entry>
830        <entry><literal>round(42.4)</literal></entry>
831        <entry><literal>42</literal></entry>
832       </row>
833
834       <row>
835        <entry><literal><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
836        <entry><type>numeric</type></entry>
837        <entry>round to <parameter>s</parameter> decimal places</entry>
838        <entry><literal>round(42.4382, 2)</literal></entry>
839        <entry><literal>42.44</literal></entry>
840       </row>
841
842       <row>
843        <entry><literal><function>setseed</function>(<type>dp</type>)</literal></entry>
844        <entry><type>void</type></entry>
845        <entry>set seed for subsequent <literal>random()</literal> calls (value between -1.0 and
846        1.0, inclusive)</entry>
847        <entry><literal>setseed(0.54823)</literal></entry>
848        <entry></entry>
849       </row>
850
851       <row>
852        <entry><literal><function>sign</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
853        <entry>(same as input)</entry>
854        <entry>sign of the argument (-1, 0, +1)</entry>
855        <entry><literal>sign(-8.4)</literal></entry>
856        <entry><literal>-1</literal></entry>
857       </row>
858
859       <row>
860        <entry><literal><function>sqrt</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
861        <entry>(same as input)</entry>
862        <entry>square root</entry>
863        <entry><literal>sqrt(2.0)</literal></entry>
864        <entry><literal>1.4142135623731</literal></entry>
865       </row>
866
867       <row>
868        <entry><literal><function>trunc</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
869        <entry>(same as input)</entry>
870        <entry>truncate toward zero</entry>
871        <entry><literal>trunc(42.8)</literal></entry>
872        <entry><literal>42</literal></entry>
873       </row>
874
875       <row>
876        <entry><literal><function>trunc</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
877        <entry><type>numeric</type></entry>
878        <entry>truncate to <parameter>s</parameter> decimal places</entry>
879        <entry><literal>trunc(42.4382, 2)</literal></entry>
880        <entry><literal>42.43</literal></entry>
881       </row>
882
883       <row>
884        <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>
885        <entry><type>int</type></entry>
886        <entry>return the bucket to which <parameter>operand</> would
887        be assigned in an equidepth histogram with <parameter>count</>
888        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
889        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
890        <entry><literal>3</literal></entry>
891       </row>
892
893       <row>
894        <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>
895        <entry><type>int</type></entry>
896        <entry>return the bucket to which <parameter>operand</> would
897        be assigned in an equidepth histogram with <parameter>count</>
898        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
899        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
900        <entry><literal>3</literal></entry>
901       </row>
902      </tbody>
903     </tgroup>
904    </table>
905
906   <para>
907    Finally, <xref linkend="functions-math-trig-table"> shows the
908    available trigonometric functions.  All trigonometric functions
909    take arguments and return values of type <type>double
910    precision</type>.
911   </para>
912
913    <indexterm>
914     <primary>acos</primary>
915    </indexterm>
916    <indexterm>
917     <primary>asin</primary>
918    </indexterm>
919    <indexterm>
920     <primary>atan</primary>
921    </indexterm>
922    <indexterm>
923     <primary>atan2</primary>
924    </indexterm>
925    <indexterm>
926     <primary>cos</primary>
927    </indexterm>
928    <indexterm>
929     <primary>cot</primary>
930    </indexterm>
931    <indexterm>
932     <primary>sin</primary>
933    </indexterm>
934    <indexterm>
935     <primary>tan</primary>
936    </indexterm>
937
938    <table id="functions-math-trig-table">
939     <title>Trigonometric Functions</title>
940
941     <tgroup cols="2">
942      <thead>
943       <row>
944        <entry>Function</entry>
945        <entry>Description</entry>
946       </row>
947      </thead>
948
949      <tbody>
950       <row>
951        <entry><literal><function>acos</function>(<replaceable>x</replaceable>)</literal></entry>
952        <entry>inverse cosine</entry>
953       </row>
954
955       <row>
956        <entry><literal><function>asin</function>(<replaceable>x</replaceable>)</literal></entry>
957        <entry>inverse sine</entry>
958       </row>
959
960       <row>
961        <entry><literal><function>atan</function>(<replaceable>x</replaceable>)</literal></entry>
962        <entry>inverse tangent</entry>
963       </row>
964
965       <row>
966        <entry><literal><function>atan2</function>(<replaceable>y</replaceable>,
967         <replaceable>x</replaceable>)</literal></entry>
968        <entry>inverse tangent of
969         <literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
970       </row>
971
972       <row>
973        <entry><literal><function>cos</function>(<replaceable>x</replaceable>)</literal></entry>
974        <entry>cosine</entry>
975       </row>
976
977       <row>
978        <entry><literal><function>cot</function>(<replaceable>x</replaceable>)</literal></entry>
979        <entry>cotangent</entry>
980       </row>
981
982       <row>
983        <entry><literal><function>sin</function>(<replaceable>x</replaceable>)</literal></entry>
984        <entry>sine</entry>
985       </row>
986
987       <row>
988        <entry><literal><function>tan</function>(<replaceable>x</replaceable>)</literal></entry>
989        <entry>tangent</entry>
990       </row>
991      </tbody>
992     </tgroup>
993    </table>
994
995   </sect1>
996
997
998   <sect1 id="functions-string">
999    <title>String Functions and Operators</title>
1000
1001    <para>
1002     This section describes functions and operators for examining and
1003     manipulating string values.  Strings in this context include values
1004     of the types <type>character</type>, <type>character varying</type>,
1005     and <type>text</type>.  Unless otherwise noted, all
1006     of the functions listed below work on all of these types, but be
1007     wary of potential effects of automatic space-padding when using the
1008     <type>character</type> type.  Some functions also exist
1009     natively for the bit-string types.
1010    </para>
1011
1012    <para>
1013     <acronym>SQL</acronym> defines some string functions with a special syntax
1014     wherein certain key words rather than commas are used to separate the
1015     arguments.  Details are in <xref linkend="functions-string-sql">.
1016     These functions are also implemented using the regular syntax for
1017     function invocation.  (See <xref linkend="functions-string-other">.)
1018    </para>
1019
1020    <note>
1021     <para>
1022      Before <productname>PostgreSQL</productname> 8.3, these functions would
1023      silently accept values of several non-string data types as well, due to
1024      the presence of implicit coercions from those data types to
1025      <type>text</>.  Those coercions have been removed because they frequently
1026      caused surprising behaviors.  However, the string concatenation operator
1027      (<literal>||</>) still accepts non-string input, so long as at least one
1028      input is of a string type, as shown in <xref
1029      linkend="functions-string-sql">.  For other cases, insert an explicit
1030      coercion to <type>text</> if you need to duplicate the previous behavior.
1031     </para>
1032    </note>
1033
1034    <indexterm>
1035     <primary>bit_length</primary>
1036    </indexterm>
1037    <indexterm>
1038     <primary>char_length</primary>
1039    </indexterm>
1040    <indexterm>
1041     <primary>lower</primary>
1042    </indexterm>
1043    <indexterm>
1044     <primary>octet_length</primary>
1045    </indexterm>
1046    <indexterm>
1047     <primary>overlay</primary>
1048    </indexterm>
1049    <indexterm>
1050     <primary>position</primary>
1051    </indexterm>
1052    <indexterm>
1053     <primary>substring</primary>
1054    </indexterm>
1055    <indexterm>
1056     <primary>trim</primary>
1057    </indexterm>
1058    <indexterm>
1059     <primary>upper</primary>
1060    </indexterm>
1061
1062    <table id="functions-string-sql">
1063     <title><acronym>SQL</acronym> String Functions and Operators</title>
1064     <tgroup cols="5">
1065      <thead>
1066       <row>
1067        <entry>Function</entry>
1068        <entry>Return Type</entry>
1069        <entry>Description</entry>
1070        <entry>Example</entry>
1071        <entry>Result</entry>  
1072       </row>
1073      </thead>
1074
1075      <tbody>
1076       <row>
1077        <entry><literal><parameter>string</parameter> <literal>||</literal>
1078         <parameter>string</parameter></literal></entry>
1079        <entry> <type>text</type> </entry>
1080        <entry>
1081         String concatenation
1082         <indexterm>
1083          <primary>character string</primary>
1084          <secondary>concatenation</secondary>
1085         </indexterm>
1086        </entry>
1087        <entry><literal>'Post' || 'greSQL'</literal></entry>
1088        <entry><literal>PostgreSQL</literal></entry>
1089       </row>
1090
1091       <row>
1092        <entry>
1093         <literal><parameter>string</parameter> <literal>||</literal>
1094         <parameter>non-string</parameter></literal>
1095         or
1096         <literal><parameter>non-string</parameter> <literal>||</literal>
1097         <parameter>string</parameter></literal>
1098        </entry>
1099        <entry> <type>text</type> </entry>
1100        <entry>
1101         String concatenation with one non-string input
1102        </entry>
1103        <entry><literal>'Value: ' || 42</literal></entry>
1104        <entry><literal>Value: 42</literal></entry>
1105       </row>
1106
1107       <row>
1108        <entry><literal><function>bit_length</function>(<parameter>string</parameter>)</literal></entry>
1109        <entry><type>int</type></entry>
1110        <entry>Number of bits in string</entry>
1111        <entry><literal>bit_length('jose')</literal></entry>
1112        <entry><literal>32</literal></entry>
1113       </row>
1114
1115       <row>
1116        <entry><literal><function>char_length</function>(<parameter>string</parameter>)</literal> or <literal><function>character_length</function>(<parameter>string</parameter>)</literal></entry>
1117        <entry><type>int</type></entry>
1118        <entry>
1119         Number of characters in string
1120         <indexterm>
1121          <primary>character string</primary>
1122          <secondary>length</secondary>
1123         </indexterm>
1124         <indexterm>
1125          <primary>length</primary>
1126          <secondary sortas="character string">of a character string</secondary>
1127          <see>character string, length</see>
1128         </indexterm>
1129        </entry>
1130        <entry><literal>char_length('jose')</literal></entry>
1131        <entry><literal>4</literal></entry>
1132       </row>
1133
1134       <row>
1135        <entry><literal><function>lower</function>(<parameter>string</parameter>)</literal></entry>
1136        <entry><type>text</type></entry>
1137        <entry>Convert string to lower case</entry>
1138        <entry><literal>lower('TOM')</literal></entry>
1139        <entry><literal>tom</literal></entry>
1140       </row>
1141
1142       <row>
1143        <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
1144        <entry><type>int</type></entry>
1145        <entry>Number of bytes in string</entry>
1146        <entry><literal>octet_length('jose')</literal></entry>
1147        <entry><literal>4</literal></entry>
1148       </row>
1149
1150       <row>
1151        <entry><literal><function>overlay</function>(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</literal></entry>
1152        <entry><type>text</type></entry>
1153        <entry>
1154         Replace substring
1155        </entry>
1156        <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
1157        <entry><literal>Thomas</literal></entry>
1158       </row>
1159
1160       <row>
1161        <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
1162        <entry><type>int</type></entry>
1163        <entry>Location of specified substring</entry>
1164        <entry><literal>position('om' in 'Thomas')</literal></entry>
1165        <entry><literal>3</literal></entry>
1166       </row>
1167
1168       <row>
1169        <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
1170        <entry><type>text</type></entry>
1171        <entry>
1172         Extract substring
1173        </entry>
1174        <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
1175        <entry><literal>hom</literal></entry>
1176       </row>
1177
1178       <row>
1179        <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</literal></entry>
1180        <entry><type>text</type></entry>
1181        <entry>
1182         Extract substring matching POSIX regular expression. See
1183         <xref linkend="functions-matching"> for more information on pattern
1184         matching.
1185        </entry>
1186        <entry><literal>substring('Thomas' from '...$')</literal></entry>
1187        <entry><literal>mas</literal></entry>
1188       </row>
1189
1190       <row>
1191        <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</literal></entry>
1192        <entry><type>text</type></entry>
1193        <entry>
1194         Extract substring matching <acronym>SQL</acronym> regular expression.
1195         See <xref linkend="functions-matching"> for more information on
1196         pattern matching.
1197        </entry>
1198        <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
1199        <entry><literal>oma</literal></entry>
1200       </row>
1201
1202       <row>
1203        <entry>
1204         <literal><function>trim</function>(<optional>leading | trailing | both</optional>
1205         <optional><parameter>characters</parameter></optional> from
1206         <parameter>string</parameter>)</literal>
1207        </entry>
1208        <entry><type>text</type></entry>
1209        <entry>
1210         Remove the longest string containing only the
1211         <parameter>characters</parameter> (a space by default) from the
1212         start/end/both ends of the <parameter>string</parameter>
1213        </entry>
1214        <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
1215        <entry><literal>Tom</literal></entry>
1216       </row>
1217
1218       <row>
1219        <entry><literal><function>upper</function>(<parameter>string</parameter>)</literal></entry>
1220        <entry><type>text</type></entry>
1221        <entry>Convert string to uppercase</entry>
1222        <entry><literal>upper('tom')</literal></entry>
1223        <entry><literal>TOM</literal></entry>
1224       </row>
1225      </tbody>
1226     </tgroup>
1227    </table>
1228
1229    <para>
1230     Additional string manipulation functions are available and are
1231     listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
1232     <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
1233    </para>
1234
1235    <indexterm>
1236     <primary>ascii</primary>
1237    </indexterm>
1238    <indexterm>
1239     <primary>btrim</primary>
1240    </indexterm>
1241    <indexterm>
1242     <primary>chr</primary>
1243    </indexterm>
1244    <indexterm>
1245     <primary>convert</primary>
1246    </indexterm>
1247    <indexterm>
1248     <primary>convert_from</primary>
1249    </indexterm>
1250    <indexterm>
1251     <primary>convert_to</primary>
1252    </indexterm>
1253    <indexterm>
1254     <primary>decode</primary>
1255    </indexterm>
1256    <indexterm>
1257     <primary>encode</primary>
1258    </indexterm>
1259    <indexterm>
1260     <primary>initcap</primary>
1261    </indexterm>
1262    <indexterm>
1263     <primary>lpad</primary>
1264    </indexterm>
1265    <indexterm>
1266     <primary>ltrim</primary>
1267    </indexterm>
1268    <indexterm>
1269     <primary>md5</primary>
1270    </indexterm>
1271    <indexterm>
1272     <primary>pg_client_encoding</primary>
1273    </indexterm>
1274    <indexterm>
1275     <primary>quote_ident</primary>
1276    </indexterm>
1277    <indexterm>
1278     <primary>quote_literal</primary>
1279    </indexterm>
1280    <indexterm>
1281     <primary>quote_nullable</primary>
1282    </indexterm>
1283    <indexterm>
1284     <primary>repeat</primary>
1285    </indexterm>
1286    <indexterm>
1287     <primary>replace</primary>
1288    </indexterm>
1289    <indexterm>
1290     <primary>rpad</primary>
1291    </indexterm>
1292    <indexterm>
1293     <primary>rtrim</primary>
1294    </indexterm>
1295    <indexterm>
1296     <primary>split_part</primary>
1297    </indexterm>
1298    <indexterm>
1299     <primary>strpos</primary>
1300    </indexterm>
1301    <indexterm>
1302     <primary>substr</primary>
1303    </indexterm>
1304    <indexterm>
1305     <primary>to_ascii</primary>
1306    </indexterm>
1307    <indexterm>
1308     <primary>to_hex</primary>
1309    </indexterm>
1310    <indexterm>
1311     <primary>translate</primary>
1312    </indexterm>
1313
1314    <table id="functions-string-other">
1315     <title>Other String Functions</title>
1316     <tgroup cols="5">
1317      <thead>
1318       <row>
1319        <entry>Function</entry>
1320        <entry>Return Type</entry>
1321        <entry>Description</entry>
1322        <entry>Example</entry>
1323        <entry>Result</entry>
1324       </row>
1325      </thead>
1326
1327      <tbody>
1328       <row>
1329        <entry><literal><function>ascii</function>(<parameter>string</parameter>)</literal></entry>
1330        <entry><type>int</type></entry>
1331        <entry>
1332         <acronym>ASCII</acronym> code of the first character of the
1333         argument.  For <acronym>UTF8</acronym> returns the Unicode code
1334         point of the character.  For other multibyte encodings, the
1335         argument must be an <acronym>ASCII</acronym> character.
1336        </entry>
1337        <entry><literal>ascii('x')</literal></entry>
1338        <entry><literal>120</literal></entry>
1339       </row>
1340
1341       <row>
1342        <entry><literal><function>btrim</function>(<parameter>string</parameter> <type>text</type>
1343        <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal></entry>
1344        <entry><type>text</type></entry>
1345        <entry>
1346         Remove the longest string consisting only of characters
1347         in <parameter>characters</parameter> (a space by default)
1348         from the start and end of <parameter>string</parameter>
1349        </entry>
1350        <entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
1351        <entry><literal>trim</literal></entry>
1352       </row>
1353
1354       <row>
1355        <entry><literal><function>chr</function>(<type>int</type>)</literal></entry>
1356        <entry><type>text</type></entry>
1357        <entry>
1358         Character with the given code. For <acronym>UTF8</acronym> the
1359         argument is treated as a Unicode code point. For other multibyte
1360         encodings the argument must designate an
1361         <acronym>ASCII</acronym> character.  The NULL (0) character is not
1362         allowed because text data types cannot store such bytes.
1363        </entry>
1364        <entry><literal>chr(65)</literal></entry>
1365        <entry><literal>A</literal></entry>
1366       </row>
1367
1368       <row>
1369        <entry>
1370         <literal><function>convert</function>(<parameter>string</parameter> <type>bytea</type>,
1371         <parameter>src_encoding</parameter> <type>name</type>,
1372         <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1373        </entry>
1374        <entry><type>bytea</type></entry>
1375        <entry>
1376         Convert string to <parameter>dest_encoding</parameter>.  The
1377         original encoding is specified by
1378         <parameter>src_encoding</parameter>. The
1379         <parameter>string</parameter> must be valid in this encoding.
1380         Conversions can be defined by <command>CREATE CONVERSION</command>.  
1381         Also there are some predefined conversions. See <xref
1382         linkend="conversion-names"> for available conversions.
1383        </entry>
1384        <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1385        <entry><literal>text_in_utf8</literal> represented in Latin-1
1386        encoding (ISO 8859-1)</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 similarly
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 that use
2589     a key word syntax, rather than commas to separate
2590     arguments.  Details are in
2591     <xref linkend="functions-binarystring-sql">.
2592     Such functions are also implemented using the regular syntax for
2593     function invocation.
2594     (See <xref linkend="functions-binarystring-other">.)
2595    </para>
2596
2597    <table id="functions-binarystring-sql">
2598     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
2599     <tgroup cols="5">
2600      <thead>
2601       <row>
2602        <entry>Function</entry>
2603        <entry>Return Type</entry>
2604        <entry>Description</entry>
2605        <entry>Example</entry>
2606        <entry>Result</entry>  
2607       </row>
2608      </thead>
2609
2610      <tbody>
2611       <row>
2612        <entry><literal><parameter>string</parameter> <literal>||</literal>
2613         <parameter>string</parameter></literal></entry>
2614        <entry> <type>bytea</type> </entry>
2615        <entry>
2616         String concatenation
2617         <indexterm>
2618          <primary>binary string</primary>
2619          <secondary>concatenation</secondary>
2620         </indexterm>
2621        </entry>
2622        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
2623        <entry><literal>\\Post'gres\000</literal></entry>
2624       </row>
2625
2626       <row>
2627        <entry><function>get_bit</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2628        <entry><type>int</type></entry>
2629        <entry>
2630         Extract bit from string
2631         <indexterm>
2632          <primary>get_bit</primary>
2633         </indexterm>
2634        </entry>
2635        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
2636        <entry><literal>1</literal></entry>
2637       </row>
2638
2639       <row>
2640        <entry><function>get_byte</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2641        <entry><type>int</type></entry>
2642        <entry>
2643         Extract byte from string
2644         <indexterm>
2645          <primary>get_byte</primary>
2646         </indexterm>
2647        </entry>
2648        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
2649        <entry><literal>109</literal></entry>
2650       </row>
2651
2652       <row>
2653        <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
2654        <entry><type>int</type></entry>
2655        <entry>Number of bytes in binary string</entry>
2656        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
2657        <entry><literal>5</literal></entry>
2658       </row>
2659
2660       <row>
2661        <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
2662        <entry><type>int</type></entry>
2663        <entry>Location of specified substring</entry>
2664       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
2665        <entry><literal>3</literal></entry>
2666       </row>
2667
2668       <row>
2669        <entry><function>set_bit</function>(<parameter>string</parameter>,
2670        <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2671        <entry><type>bytea</type></entry>
2672        <entry>
2673         Set bit in string
2674         <indexterm>
2675          <primary>set_bit</primary>
2676         </indexterm>
2677        </entry>
2678        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
2679        <entry><literal>Th\000omAs</literal></entry>
2680       </row>
2681
2682       <row>
2683        <entry><function>set_byte</function>(<parameter>string</parameter>,
2684        <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2685        <entry><type>bytea</type></entry>
2686        <entry>
2687         Set byte in string
2688         <indexterm>
2689          <primary>set_byte</primary>
2690         </indexterm>
2691        </entry>
2692        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
2693        <entry><literal>Th\000o@as</literal></entry>
2694       </row>
2695
2696       <row>
2697        <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
2698        <entry><type>bytea</type></entry>
2699        <entry>
2700         Extract substring
2701         <indexterm>
2702          <primary>substring</primary>
2703         </indexterm>
2704        </entry>
2705        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
2706        <entry><literal>h\000o</literal></entry>
2707       </row>
2708
2709       <row>
2710        <entry>
2711         <literal><function>trim</function>(<optional>both</optional>
2712         <parameter>bytes</parameter> from
2713         <parameter>string</parameter>)</literal>
2714        </entry>
2715        <entry><type>bytea</type></entry>
2716        <entry>
2717         Remove the longest string containing only the bytes in
2718         <parameter>bytes</parameter> from the start
2719         and end of <parameter>string</parameter>
2720        </entry>
2721        <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
2722        <entry><literal>Tom</literal></entry>
2723       </row>
2724      </tbody>
2725     </tgroup>
2726    </table>
2727
2728    <para>
2729     Additional binary string manipulation functions are available and
2730     are listed in <xref linkend="functions-binarystring-other">.  Some
2731     of them are used internally to implement the
2732     <acronym>SQL</acronym>-standard string functions listed in <xref
2733     linkend="functions-binarystring-sql">.
2734    </para>
2735
2736    <table id="functions-binarystring-other">
2737     <title>Other Binary String Functions</title>
2738     <tgroup cols="5">
2739      <thead>
2740       <row>
2741        <entry>Function</entry>
2742        <entry>Return Type</entry>
2743        <entry>Description</entry>
2744        <entry>Example</entry>
2745        <entry>Result</entry>
2746       </row>
2747      </thead>
2748
2749      <tbody>
2750       <row>
2751        <entry><literal><function>btrim</function>(<parameter>string</parameter>
2752         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</literal></entry>
2753        <entry><type>bytea</type></entry>
2754        <entry>
2755         Remove the longest string consisting only of bytes
2756         in <parameter>bytes</parameter> from the start and end of
2757         <parameter>string</parameter>
2758       </entry>
2759       <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
2760       <entry><literal>trim</literal></entry>
2761      </row>
2762
2763      <row>
2764       <entry>
2765        <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
2766               <parameter>type</parameter> <type>text</type>)</literal>
2767       </entry>
2768       <entry><type>bytea</type></entry>
2769       <entry>
2770        Decode binary string from <parameter>string</parameter> previously 
2771        encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
2772       </entry>
2773       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
2774       <entry><literal>123\000456</literal></entry>
2775      </row>
2776
2777      <row>
2778       <entry>
2779        <literal><function>encode</function>(<parameter>string</parameter> <type>bytea</type>,
2780               <parameter>type</parameter> <type>text</type>)</literal>
2781       </entry>
2782       <entry><type>text</type></entry>
2783       <entry>
2784        Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
2785        types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
2786       </entry>
2787       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
2788       <entry><literal>123\000456</literal></entry>
2789      </row>
2790
2791      <row>
2792       <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
2793       <entry><type>int</type></entry>
2794       <entry>
2795        Length of binary string
2796        <indexterm>
2797         <primary>binary string</primary>
2798         <secondary>length</secondary>
2799        </indexterm>
2800        <indexterm>
2801         <primary>length</primary>
2802         <secondary sortas="binary string">of a binary string</secondary>
2803         <see>binary strings, length</see>
2804        </indexterm>
2805       </entry>
2806       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
2807       <entry><literal>5</literal></entry>
2808      </row>
2809
2810      <row>
2811       <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
2812       <entry><type>text</type></entry>
2813       <entry>
2814        Calculates the MD5 hash of <parameter>string</parameter>,
2815        returning the result in hexadecimal
2816       </entry>
2817       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
2818       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
2819      </row>
2820     </tbody>
2821    </tgroup>
2822   </table>
2823
2824  </sect1>
2825
2826
2827   <sect1 id="functions-bitstring">
2828    <title>Bit String Functions and Operators</title>
2829
2830    <indexterm zone="functions-bitstring">
2831     <primary>bit strings</primary>
2832     <secondary>functions</secondary>
2833    </indexterm>
2834
2835    <para>
2836     This section describes functions and operators for examining and
2837     manipulating bit strings, that is values of the types
2838     <type>bit</type> and <type>bit varying</type>.  Aside from the
2839     usual comparison operators, the operators
2840     shown in <xref linkend="functions-bit-string-op-table"> can be used.
2841     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
2842     and <literal>#</literal> must be of equal length.  When bit
2843     shifting, the original length of the string is preserved, as shown
2844     in the examples.
2845    </para>
2846
2847    <table id="functions-bit-string-op-table">
2848     <title>Bit String Operators</title>
2849
2850     <tgroup cols="4">
2851      <thead>
2852       <row>
2853        <entry>Operator</entry>
2854        <entry>Description</entry>
2855        <entry>Example</entry>
2856        <entry>Result</entry>
2857       </row>
2858      </thead>
2859
2860      <tbody>
2861       <row>
2862        <entry> <literal>||</literal> </entry>
2863        <entry>concatenation</entry>
2864        <entry><literal>B'10001' || B'011'</literal></entry>
2865        <entry><literal>10001011</literal></entry>
2866       </row>
2867
2868       <row>
2869        <entry> <literal>&amp;</literal> </entry>
2870        <entry>bitwise AND</entry>
2871        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
2872        <entry><literal>00001</literal></entry>
2873       </row>
2874
2875       <row>
2876        <entry> <literal>|</literal> </entry>
2877        <entry>bitwise OR</entry>
2878        <entry><literal>B'10001' | B'01101'</literal></entry>
2879        <entry><literal>11101</literal></entry>
2880       </row>
2881
2882       <row>
2883        <entry> <literal>#</literal> </entry>
2884        <entry>bitwise XOR</entry>
2885        <entry><literal>B'10001' # B'01101'</literal></entry>
2886        <entry><literal>11100</literal></entry>
2887       </row>
2888
2889       <row>
2890        <entry> <literal>~</literal> </entry>
2891        <entry>bitwise NOT</entry>
2892        <entry><literal>~ B'10001'</literal></entry>
2893        <entry><literal>01110</literal></entry>
2894       </row>
2895
2896       <row>
2897        <entry> <literal>&lt;&lt;</literal> </entry>
2898        <entry>bitwise shift left</entry>
2899        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
2900        <entry><literal>01000</literal></entry>
2901       </row>
2902
2903       <row>
2904        <entry> <literal>&gt;&gt;</literal> </entry>
2905        <entry>bitwise shift right</entry>
2906        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
2907        <entry><literal>00100</literal></entry>
2908       </row>
2909      </tbody>
2910     </tgroup>
2911    </table>
2912
2913    <para>
2914     The following <acronym>SQL</acronym>-standard functions work on bit
2915     strings as well as character strings:
2916     <literal><function>length</function></literal>,
2917     <literal><function>bit_length</function></literal>,
2918     <literal><function>octet_length</function></literal>,
2919     <literal><function>position</function></literal>,
2920     <literal><function>substring</function></literal>.
2921    </para>
2922
2923    <para>
2924     In addition, it is possible to cast integral values to and from type
2925     <type>bit</>.
2926     Some examples:
2927 <programlisting>
2928 44::bit(10)                    <lineannotation>0000101100</lineannotation>
2929 44::bit(3)                     <lineannotation>100</lineannotation>
2930 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
2931 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
2932 </programlisting>
2933     Note that casting to just <quote>bit</> means casting to
2934     <literal>bit(1)</>, and so will deliver only the least significant
2935     bit of the integer.
2936    </para>
2937
2938     <note>
2939      <para>
2940       Prior to <productname>PostgreSQL</productname> 8.0, casting an
2941       integer to <type>bit(n)</> would copy the leftmost <literal>n</>
2942       bits of the integer, whereas now it copies the rightmost <literal>n</>
2943       bits.  Also, casting an integer to a bit string width wider than
2944       the integer itself will sign-extend on the left.
2945      </para>
2946     </note>
2947
2948   </sect1>
2949
2950
2951  <sect1 id="functions-matching">
2952   <title>Pattern Matching</title>
2953
2954   <indexterm zone="functions-matching">
2955    <primary>pattern matching</primary>
2956   </indexterm>
2957
2958    <para>
2959     There are three separate approaches to pattern matching provided
2960     by <productname>PostgreSQL</productname>: the traditional
2961     <acronym>SQL</acronym> <function>LIKE</function> operator, the
2962     more recent <function>SIMILAR TO</function> operator (added in
2963     SQL:1999), and <acronym>POSIX</acronym>-style regular
2964     expressions.  Aside from the basic <quote>does this string match
2965     this pattern?</> operators, functions are available to extract
2966     or replace matching substrings and to split a string at matching
2967     locations.
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      The <function>LIKE</function> expression returns true if
2991      <replaceable>string</replaceable> matches the supplied
2992      <replaceable>pattern</replaceable>.  (As
2993      expected, the <function>NOT LIKE</function> expression returns
2994      false if <function>LIKE</function> returns true, and vice versa.
2995      An equivalent expression is
2996      <literal>NOT (<replaceable>string</replaceable> LIKE
2997       <replaceable>pattern</replaceable>)</literal>.)
2998     </para>
2999
3000     <para>
3001      If <replaceable>pattern</replaceable> does not contain percent
3002      signs or underscore, then the pattern only represents the string
3003      itself; in that case <function>LIKE</function> acts like the
3004      equals operator.  An underscore (<literal>_</literal>) in
3005      <replaceable>pattern</replaceable> stands for (matches) any single
3006      character; a percent sign (<literal>%</literal>) matches any string
3007      of zero or more characters.
3008     </para>
3009
3010    <para>
3011     Some examples:
3012 <programlisting>
3013 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
3014 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
3015 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
3016 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
3017 </programlisting>
3018    </para>
3019    
3020    <para>
3021     <function>LIKE</function> pattern matching always covers the entire
3022     string.  Therefore, to match a sequence anywhere within a string, the
3023     pattern must start and end with a percent sign.
3024    </para>
3025
3026    <para>
3027     To match only a literal underscore or percent sign without matching
3028     other characters, the respective character in
3029     <replaceable>pattern</replaceable> must be 
3030     preceded by the escape character.  The default escape
3031     character is the backslash but a different one can be selected by
3032     using the <literal>ESCAPE</literal> clause.  To match the escape
3033     character itself, write two escape characters.
3034    </para>
3035
3036    <para>
3037     Note that the backslash already has a special meaning in string literals,
3038     so to write a pattern constant that contains a backslash you must write two
3039     backslashes in an SQL statement (assuming escape string syntax is used, see
3040     <xref linkend="sql-syntax-strings">).  Thus, writing a pattern that
3041     actually matches a literal backslash means writing four backslashes in the
3042     statement.  You can avoid this by selecting a different escape character
3043     with <literal>ESCAPE</literal>; then a backslash is not special to
3044     <function>LIKE</function> anymore. (But backslash is still special to the string
3045     literal parser, so you still need two of them.)
3046    </para>
3047
3048    <para>
3049     It's also possible to select no escape character by writing
3050     <literal>ESCAPE ''</literal>.  This effectively disables the
3051     escape mechanism, which makes it impossible to turn off the
3052     special meaning of underscore and percent signs in the pattern.
3053    </para>
3054
3055    <para>
3056     The key word <token>ILIKE</token> can be used instead of
3057     <token>LIKE</token> to make the match case-insensitive according
3058     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3059     <productname>PostgreSQL</productname> extension.
3060    </para>
3061
3062    <para>
3063     The operator <literal>~~</literal> is equivalent to
3064     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3065     <function>ILIKE</function>.  There are also
3066     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3067     represent <function>NOT LIKE</function> and <function>NOT
3068     ILIKE</function>, respectively.  All of these operators are
3069     <productname>PostgreSQL</productname>-specific.
3070    </para>
3071   </sect2>
3072
3073
3074   <sect2 id="functions-similarto-regexp">
3075    <title><function>SIMILAR TO</function> Regular Expressions</title>
3076
3077    <indexterm>
3078     <primary>regular expression</primary>
3079     <!-- <seealso>pattern matching</seealso> breaks index build -->
3080    </indexterm>
3081
3082    <indexterm>
3083     <primary>SIMILAR TO</primary>
3084    </indexterm>
3085    <indexterm>
3086     <primary>substring</primary>
3087    </indexterm>
3088
3089 <synopsis>
3090 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3091 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3092 </synopsis>
3093
3094    <para>
3095     The <function>SIMILAR TO</function> operator returns true or
3096     false depending on whether its pattern matches the given string.
3097     It is similar to <function>LIKE</function>, except that it
3098     interprets the pattern using the SQL standard's definition of a
3099     regular expression.  SQL regular expressions are a curious cross
3100     between <function>LIKE</function> notation and common regular
3101     expression notation.
3102    </para>
3103
3104    <para>
3105     Like <function>LIKE</function>, the <function>SIMILAR TO</function>
3106     operator succeeds only if its pattern matches the entire string;
3107     this is unlike common regular expression behavior where the pattern
3108     can match any part of the string.
3109     Also like
3110     <function>LIKE</function>, <function>SIMILAR TO</function> uses
3111     <literal>_</> and <literal>%</> as wildcard characters denoting
3112     any single character and any string, respectively (these are
3113     comparable to <literal>.</> and <literal>.*</> in POSIX regular
3114     expressions).
3115    </para>
3116
3117    <para>
3118     In addition to these facilities borrowed from <function>LIKE</function>,
3119     <function>SIMILAR TO</function> supports these pattern-matching
3120     metacharacters borrowed from POSIX regular expressions:
3121
3122    <itemizedlist>
3123     <listitem>
3124      <para>
3125       <literal>|</literal> denotes alternation (either of two alternatives).
3126      </para>
3127     </listitem>
3128     <listitem>
3129      <para>
3130       <literal>*</literal> denotes repetition of the previous item zero
3131       or more times.
3132      </para>
3133     </listitem>
3134     <listitem>
3135      <para>
3136       <literal>+</literal> denotes repetition of the previous item one
3137       or more times.
3138      </para>
3139     </listitem>
3140     <listitem>
3141      <para>
3142       Parentheses <literal>()</literal> can be used to group items into
3143       a single logical item.
3144      </para>
3145     </listitem>
3146     <listitem>
3147      <para>
3148       A bracket expression <literal>[...]</literal> specifies a character
3149       class, just as in POSIX regular expressions.
3150      </para>
3151     </listitem>
3152    </itemizedlist>
3153
3154     Notice that bounded repetition (<literal>?</> and <literal>{...}</>)
3155     is not provided, though they exist in POSIX.  Also, the period (<literal>.</>)
3156     is not a metacharacter.
3157    </para>
3158
3159    <para>
3160     As with <function>LIKE</>, a backslash disables the special meaning
3161     of any of these metacharacters; or a different escape character can
3162     be specified with <literal>ESCAPE</>.
3163    </para>
3164
3165    <para>
3166     Some examples:
3167 <programlisting>
3168 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
3169 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
3170 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
3171 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
3172 </programlisting>
3173    </para>
3174
3175    <para>
3176     The <function>substring</> function with three parameters,
3177     <function>substring(<replaceable>string</replaceable> from
3178     <replaceable>pattern</replaceable> for
3179     <replaceable>escape-character</replaceable>)</function>, provides
3180     extraction of a substring that matches an SQL
3181     regular expression pattern.  As with <literal>SIMILAR TO</>, the
3182     specified pattern must match the entire data string, or else the
3183     function fails and returns null.  To indicate the part of the
3184     pattern that should be returned on success, the pattern must contain
3185     two occurrences of the escape character followed by a double quote
3186     (<literal>"</>). <!-- " font-lock sanity -->
3187     The text matching the portion of the pattern
3188     between these markers is returned.
3189    </para>
3190
3191    <para>
3192     Some examples, with <literal>#"</> delimiting the return string:
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>.
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 software package written by Henry Spencer.  Much of
3508     the description of regular expressions below is copied verbatim from his
3509     manual.
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
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 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 tries a match of 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 cannot be followed by a quantifier.
3571     The simple constraints are shown in
3572     <xref linkend="posix-constraints-table">;
3573     some more constraints are described later.
3574    </para>
3575
3576
3577    <table id="posix-atoms-table">
3578     <title>Regular Expression Atoms</title>
3579
3580     <tgroup cols="2">
3581      <thead>
3582       <row>
3583        <entry>Atom</entry>
3584        <entry>Description</entry>
3585       </row>
3586      </thead>
3587
3588       <tbody>
3589        <row>
3590        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3591        <entry> (where <replaceable>re</> is any regular expression)
3592        matches a match for
3593        <replaceable>re</>, with the match noted for possible reporting </entry>
3594        </row>
3595
3596        <row>
3597        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3598        <entry> as above, but the match is not noted for reporting
3599        (a <quote>non-capturing</> set of parentheses)
3600        (AREs only) </entry>
3601        </row>
3602
3603        <row>
3604        <entry> <literal>.</> </entry>
3605        <entry> matches any single character </entry>
3606        </row>
3607
3608        <row>
3609        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
3610        <entry> a <firstterm>bracket expression</>,
3611        matching any one of the <replaceable>chars</> (see
3612        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
3613        </row>
3614
3615        <row>
3616        <entry> <literal>\</><replaceable>k</> </entry>
3617        <entry> (where <replaceable>k</> is a non-alphanumeric character)
3618        matches that character taken as an ordinary character,
3619        e.g., <literal>\\</> matches a backslash character </entry>
3620        </row>
3621
3622        <row>
3623        <entry> <literal>\</><replaceable>c</> </entry>
3624        <entry> where <replaceable>c</> is alphanumeric
3625        (possibly followed by other characters)
3626        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
3627        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
3628        </row>
3629
3630        <row>
3631        <entry> <literal>{</> </entry>
3632        <entry> when followed by a character other than a digit,
3633        matches the left-brace character <literal>{</>;
3634        when followed by a digit, it is the beginning of a
3635        <replaceable>bound</> (see below) </entry>
3636        </row>
3637
3638        <row>
3639        <entry> <replaceable>x</> </entry>
3640        <entry> where <replaceable>x</> is a single character with no other
3641        significance, matches that character </entry>
3642        </row>
3643       </tbody>
3644      </tgroup>
3645     </table>
3646
3647    <para>
3648     An RE cannot end with <literal>\</>.
3649    </para>
3650
3651    <note>
3652     <para>
3653      Remember that the backslash (<literal>\</literal>) already has a special
3654      meaning in <productname>PostgreSQL</> string literals.
3655      To write a pattern constant that contains a backslash,
3656      you must write two backslashes in the statement, assuming escape
3657      string syntax is used (see <xref linkend="sql-syntax-strings">).
3658     </para>
3659    </note>
3660
3661    <table id="posix-quantifiers-table">
3662     <title>Regular Expression Quantifiers</title>
3663
3664     <tgroup cols="2">
3665      <thead>
3666       <row>
3667        <entry>Quantifier</entry>
3668        <entry>Matches</entry>
3669       </row>
3670      </thead>
3671
3672       <tbody>
3673        <row>
3674        <entry> <literal>*</> </entry>
3675        <entry> a sequence of 0 or more matches of the atom </entry>
3676        </row>
3677
3678        <row>
3679        <entry> <literal>+</> </entry>
3680        <entry> a sequence of 1 or more matches of the atom </entry>
3681        </row>
3682
3683        <row>
3684        <entry> <literal>?</> </entry>
3685        <entry> a sequence of 0 or 1 matches of the atom </entry>
3686        </row>
3687
3688        <row>
3689        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
3690        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
3691        </row>
3692
3693        <row>
3694        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
3695        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
3696        </row>
3697
3698        <row>
3699        <entry>
3700        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3701        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
3702        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
3703        <replaceable>n</> </entry>
3704        </row>
3705
3706        <row>
3707        <entry> <literal>*?</> </entry>
3708        <entry> non-greedy version of <literal>*</> </entry>
3709        </row>
3710
3711        <row>
3712        <entry> <literal>+?</> </entry>
3713        <entry> non-greedy version of <literal>+</> </entry>
3714        </row>
3715
3716        <row>
3717        <entry> <literal>??</> </entry>
3718        <entry> non-greedy version of <literal>?</> </entry>
3719        </row>
3720
3721        <row>
3722        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
3723        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
3724        </row>
3725
3726        <row>
3727        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
3728        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
3729        </row>
3730
3731        <row>
3732        <entry>
3733        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
3734        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3735        </row>
3736       </tbody>
3737      </tgroup>
3738     </table>
3739
3740    <para>
3741     The forms using <literal>{</><replaceable>...</><literal>}</>
3742     are known as <firstterm>bounds</>.
3743     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
3744     unsigned decimal integers with permissible values from 0 to 255 inclusive.
3745    </para>
3746
3747     <para>
3748      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
3749      same possibilities as their corresponding normal (<firstterm>greedy</>)
3750      counterparts, but prefer the smallest number rather than the largest
3751      number of matches.
3752      See <xref linkend="posix-matching-rules"> for more detail.
3753    </para>
3754
3755    <note>
3756     <para>
3757      A quantifier cannot immediately follow another quantifier, e.g.,
3758      <literal>**</> is invalid.
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 the beginning of the string </entry>
3780        </row>
3781
3782        <row>
3783        <entry> <literal>$</> </entry>
3784        <entry> matches 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 (possibly following a <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 start 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 and
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     treated as a single element of the bracket expression's list.  This
3854     allows a bracket
3855     expression containing a multiple-character collating element to
3856     match more than one character, e.g., if the collating sequence
3857     includes a <literal>ch</literal> collating element, then the RE
3858     <literal>[[.ch.]]*c</literal> matches the first five characters of
3859     <literal>chchcc</literal>.
3860    </para>
3861
3862    <note>
3863     <para>
3864      <productname>PostgreSQL</> currently does not support multi-character collating
3865      elements. This information describes possible future behavior.
3866     </para>
3867    </note>
3868
3869    <para>
3870     Within a bracket expression, a collating element enclosed in
3871     <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
3872     class</>, standing for the sequences of characters of all collating
3873     elements equivalent to that one, including itself.  (If there are
3874     no other equivalent collating elements, the treatment is as if the
3875     enclosing delimiters were <literal>[.</literal> and
3876     <literal>.]</literal>.)  For example, if <literal>o</literal> and
3877     <literal>^</literal> are the members of an equivalence class, then
3878     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
3879     <literal>[o^]</literal> are all synonymous.  An equivalence class
3880     cannot be an endpoint of a range.
3881    </para>
3882
3883    <para>
3884     Within a bracket expression, the name of a character class
3885     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
3886     for the list of all characters belonging to that class.  Standard
3887     character class names are: <literal>alnum</literal>,
3888     <literal>alpha</literal>, <literal>blank</literal>,
3889     <literal>cntrl</literal>, <literal>digit</literal>,
3890     <literal>graph</literal>, <literal>lower</literal>,
3891     <literal>print</literal>, <literal>punct</literal>,
3892     <literal>space</literal>, <literal>upper</literal>,
3893     <literal>xdigit</literal>.  These stand for the character classes
3894     defined in
3895     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
3896     A locale can provide others.  A character class cannot be used as
3897     an endpoint of a range.
3898    </para>
3899
3900    <para>
3901     There are two special cases of bracket expressions:  the bracket
3902     expressions <literal>[[:&lt;:]]</literal> and
3903     <literal>[[:&gt;:]]</literal> are constraints,
3904     matching empty strings at the beginning
3905     and end of a word respectively.  A word is defined as a sequence
3906     of word characters that is neither preceded nor followed by word
3907     characters.  A word character is an <literal>alnum</> character (as
3908     defined by
3909     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
3910     or an underscore.  This is an extension, compatible with but not
3911     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
3912     caution in software intended to be portable to other systems.
3913     The constraint escapes described below are usually preferable; they
3914     are no more standard, but are easier to type.
3915    </para>
3916    </sect3>
3917
3918    <sect3 id="posix-escape-sequences">
3919     <title>Regular Expression Escapes</title>
3920
3921    <para>
3922     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
3923     followed by an alphanumeric character. Escapes come in several varieties:
3924     character entry, class shorthands, constraint escapes, and back references.
3925     A <literal>\</> followed by an alphanumeric character but not constituting
3926     a valid escape is illegal in AREs.
3927     In EREs, there are no escapes: outside a bracket expression,
3928     a <literal>\</> followed by an alphanumeric character merely stands for
3929     that character as an ordinary character, and inside a bracket expression,
3930     <literal>\</> is an ordinary character.
3931     (The latter is the one actual incompatibility between EREs and AREs.)
3932    </para>
3933
3934    <para>
3935     <firstterm>Character-entry escapes</> exist to make it easier to specify
3936     non-printing and inconvenient characters in REs.  They are
3937     shown in <xref linkend="posix-character-entry-escapes-table">.
3938    </para>
3939
3940    <para>
3941     <firstterm>Class-shorthand escapes</> provide shorthands for certain
3942     commonly-used character classes.  They are
3943     shown in <xref linkend="posix-class-shorthand-escapes-table">.
3944    </para>
3945
3946    <para>
3947     A <firstterm>constraint escape</> is a constraint,
3948     matching the empty string if specific conditions are met,
3949     written as an escape.  They are
3950     shown in <xref linkend="posix-constraint-escapes-table">.
3951    </para>
3952
3953    <para>
3954     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
3955     same string matched by the previous parenthesized subexpression specified
3956     by the number <replaceable>n</>
3957     (see <xref linkend="posix-constraint-backref-table">).  For example,
3958     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
3959     but not <literal>bc</> or <literal>cb</>.
3960     The subexpression must entirely precede the back reference in the RE.
3961     Subexpressions are numbered in the order of their leading parentheses.
3962     Non-capturing parentheses do not define subexpressions.
3963    </para>
3964
3965    <note>
3966     <para>
3967      Keep in mind that an escape's leading <literal>\</> will need to be
3968      doubled when entering the pattern as an SQL string constant.  For example:
3969 <programlisting>
3970 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
3971 </programlisting>
3972     </para>
3973    </note>
3974
3975    <table id="posix-character-entry-escapes-table">
3976     <title>Regular Expression Character-Entry Escapes</title>
3977
3978     <tgroup cols="2">
3979      <thead>
3980       <row>
3981        <entry>Escape</entry>
3982        <entry>Description</entry>
3983       </row>
3984      </thead>
3985
3986       <tbody>
3987        <row>
3988        <entry> <literal>\a</> </entry>
3989        <entry> alert (bell) character, as in C </entry>
3990        </row>
3991
3992        <row>
3993        <entry> <literal>\b</> </entry>
3994        <entry> backspace, as in C </entry>
3995        </row>
3996
3997        <row>
3998        <entry> <literal>\B</> </entry>
3999        <entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
4000        doubling </entry>
4001        </row>
4002
4003        <row>
4004        <entry> <literal>\c</><replaceable>X</> </entry>
4005        <entry> (where <replaceable>X</> is any character) the character whose
4006        low-order 5 bits are the same as those of
4007        <replaceable>X</>, and whose other bits are all zero </entry>
4008        </row>
4009
4010        <row>
4011        <entry> <literal>\e</> </entry>
4012        <entry> the character whose collating-sequence name
4013        is <literal>ESC</>,
4014        or failing that, the character with octal value 033 </entry>
4015        </row>
4016
4017        <row>
4018        <entry> <literal>\f</> </entry>
4019        <entry> form feed, as in C </entry>
4020        </row>
4021
4022        <row>
4023        <entry> <literal>\n</> </entry>
4024        <entry> newline, as in C </entry>
4025        </row>
4026
4027        <row>
4028        <entry> <literal>\r</> </entry>
4029        <entry> carriage return, as in C </entry>
4030        </row>
4031
4032        <row>
4033        <entry> <literal>\t</> </entry>
4034        <entry> horizontal tab, as in C </entry>
4035        </row>
4036
4037        <row>
4038        <entry> <literal>\u</><replaceable>wxyz</> </entry>
4039        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4040        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4041        in the local byte encoding</entry>
4042        </row>
4043
4044        <row>
4045        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4046        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4047        digits)
4048        reserved for a hypothetical Unicode extension to 32 bits
4049        </entry> 
4050        </row>
4051
4052        <row>
4053        <entry> <literal>\v</> </entry>
4054        <entry> vertical tab, as in C </entry>
4055        </row>
4056
4057        <row>
4058        <entry> <literal>\x</><replaceable>###</> </entry>
4059        <entry> (where <replaceable>###</> is any sequence of hexadecimal
4060        digits)
4061        the character whose hexadecimal value is
4062        <literal>0x</><replaceable>###</>
4063        (a single character no matter how many hexadecimal digits are used)
4064        </entry>
4065        </row>
4066
4067        <row>
4068        <entry> <literal>\0</> </entry>
4069        <entry> the character whose value is <literal>0</> (the null byte)</entry>
4070        </row>
4071
4072        <row>
4073        <entry> <literal>\</><replaceable>##</> </entry>
4074        <entry> (where <replaceable>##</> is exactly two octal digits,
4075        and is not a <firstterm>back reference</>)
4076        the character whose octal value is
4077        <literal>0</><replaceable>##</> </entry>
4078        </row>
4079
4080        <row>
4081        <entry> <literal>\</><replaceable>###</> </entry>
4082        <entry> (where <replaceable>###</> is exactly three octal digits,
4083        and is not a <firstterm>back reference</>)
4084        the character whose octal value is
4085        <literal>0</><replaceable>###</> </entry>
4086        </row>
4087       </tbody>
4088      </tgroup>
4089     </table>
4090
4091    <para>
4092     Hexadecimal digits are <literal>0</>-<literal>9</>,
4093     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4094     Octal digits are <literal>0</>-<literal>7</>.
4095    </para>
4096
4097    <para>
4098     The character-entry escapes are always taken as ordinary characters.
4099     For example, <literal>\135</> is <literal>]</> in ASCII, but
4100     <literal>\135</> does not terminate a bracket expression.
4101    </para>
4102
4103    <table id="posix-class-shorthand-escapes-table">
4104     <title>Regular Expression Class-Shorthand Escapes</title>
4105
4106     <tgroup cols="2">
4107      <thead>
4108       <row>
4109        <entry>Escape</entry>
4110        <entry>Description</entry>
4111       </row>
4112      </thead>
4113
4114       <tbody>
4115        <row>
4116        <entry> <literal>\d</> </entry>
4117        <entry> <literal>[[:digit:]]</> </entry>
4118        </row>
4119
4120        <row>
4121        <entry> <literal>\s</> </entry>
4122        <entry> <literal>[[:space:]]</> </entry>
4123        </row>
4124
4125        <row>
4126        <entry> <literal>\w</> </entry>
4127        <entry> <literal>[[:alnum:]_]</>
4128        (note underscore is included) </entry>
4129        </row>
4130
4131        <row>
4132        <entry> <literal>\D</> </entry>
4133        <entry> <literal>[^[:digit:]]</> </entry>
4134        </row>
4135
4136        <row>
4137        <entry> <literal>\S</> </entry>
4138        <entry> <literal>[^[:space:]]</> </entry>
4139        </row>
4140
4141        <row>
4142        <entry> <literal>\W</> </entry>
4143        <entry> <literal>[^[:alnum:]_]</>
4144        (note underscore is included) </entry>
4145        </row>
4146       </tbody>
4147      </tgroup>
4148     </table>
4149
4150    <para>
4151     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4152     and <literal>\w</> lose their outer brackets,
4153     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4154     (So, for example, <literal>[a-c\d]</> is equivalent to
4155     <literal>[a-c[:digit:]]</>.
4156     Also, <literal>[a-c\D]</>, which is equivalent to
4157     <literal>[a-c^[:digit:]]</>, is illegal.)
4158    </para>
4159
4160    <table id="posix-constraint-escapes-table">
4161     <title>Regular Expression Constraint Escapes</title>
4162
4163     <tgroup cols="2">
4164      <thead>
4165       <row>
4166        <entry>Escape</entry>
4167        <entry>Description</entry>
4168       </row>
4169      </thead>
4170
4171       <tbody>
4172        <row>
4173        <entry> <literal>\A</> </entry>
4174        <entry> matches only at the beginning of the string
4175        (see <xref linkend="posix-matching-rules"> for how this differs from
4176        <literal>^</>) </entry>
4177        </row>
4178
4179        <row>
4180        <entry> <literal>\m</> </entry>
4181        <entry> matches only at the beginning of a word </entry>
4182        </row>
4183
4184        <row>
4185        <entry> <literal>\M</> </entry>
4186        <entry> matches only at the end of a word </entry>
4187        </row>
4188
4189        <row>
4190        <entry> <literal>\y</> </entry>
4191        <entry> matches only at the beginning or end of a word </entry>
4192        </row>
4193
4194        <row>
4195        <entry> <literal>\Y</> </entry>
4196        <entry> matches only at a point that is not the beginning or end of a
4197        word </entry>
4198        </row>
4199
4200        <row>
4201        <entry> <literal>\Z</> </entry>
4202        <entry> matches only at the end of the string
4203        (see <xref linkend="posix-matching-rules"> for how this differs from
4204        <literal>$</>) </entry>
4205        </row>
4206       </tbody>
4207      </tgroup>
4208     </table>
4209
4210    <para>
4211     A word is defined as in the specification of
4212     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4213     Constraint escapes are illegal within bracket expressions.
4214    </para>
4215
4216    <table id="posix-constraint-backref-table">
4217     <title>Regular Expression Back References</title>
4218
4219     <tgroup cols="2">
4220      <thead>
4221       <row>
4222        <entry>Escape</entry>
4223        <entry>Description</entry>
4224       </row>
4225      </thead>
4226
4227       <tbody>
4228        <row>
4229        <entry> <literal>\</><replaceable>m</> </entry>
4230        <entry> (where <replaceable>m</> is a nonzero digit)
4231        a back reference to the <replaceable>m</>'th subexpression </entry>
4232        </row>
4233
4234        <row>
4235        <entry> <literal>\</><replaceable>mnn</> </entry>
4236        <entry> (where <replaceable>m</> is a nonzero digit, and
4237        <replaceable>nn</> is some more digits, and the decimal value
4238        <replaceable>mnn</> is not greater than the number of closing capturing
4239        parentheses seen so far) 
4240        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4241        </row>
4242       </tbody>
4243      </tgroup>
4244     </table>
4245
4246    <note>
4247     <para>
4248      There is an inherent ambiguity between octal character-entry
4249      escapes and back references, which is resolved by heuristics,
4250      as hinted at above.
4251      A leading zero always indicates an octal escape.
4252      A single non-zero digit, not followed by another digit,
4253      is always taken as a back reference.
4254      A multidigit sequence not starting with a zero is taken as a back 
4255      reference if it comes after a suitable subexpression
4256      (i.e., the number is in the legal range for a back reference),
4257      and otherwise is taken as octal.
4258     </para>
4259    </note>
4260    </sect3>
4261
4262    <sect3 id="posix-metasyntax">
4263     <title>Regular Expression Metasyntax</title>
4264
4265    <para>
4266     In addition to the main syntax described above, there are some special
4267     forms and miscellaneous syntactic facilities available.
4268    </para>
4269
4270    <para>
4271     Normally the flavor of RE being used is determined by
4272     <varname>regex_flavor</>.
4273     However, this can be overridden by a <firstterm>director</> prefix.
4274     If an RE begins with <literal>***:</>,
4275     the rest of the RE is taken as an ARE regardless of
4276     <varname>regex_flavor</>.
4277     If an RE begins with <literal>***=</>,
4278     the rest of the RE is taken to be a literal string,
4279     with all characters considered ordinary characters.
4280    </para>
4281
4282    <para>
4283     An ARE can begin with <firstterm>embedded options</>:
4284     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4285     (where <replaceable>xyz</> is one or more alphabetic characters)
4286     specifies options affecting the rest of the RE.
4287     These options override any previously determined options (including
4288     both the RE flavor and case sensitivity).
4289     The available option letters are
4290     shown in <xref linkend="posix-embedded-options-table">.
4291    </para>
4292
4293    <table id="posix-embedded-options-table">
4294     <title>ARE Embedded-Option Letters</title>
4295
4296     <tgroup cols="2">
4297      <thead>
4298       <row>
4299        <entry>Option</entry>
4300        <entry>Description</entry>
4301       </row>
4302      </thead>
4303
4304       <tbody>
4305        <row>
4306        <entry> <literal>b</> </entry>
4307        <entry> rest of RE is a BRE </entry>
4308        </row>
4309
4310        <row>
4311        <entry> <literal>c</> </entry>
4312        <entry> case-sensitive matching (overrides operator type) </entry>
4313        </row>
4314
4315        <row>
4316        <entry> <literal>e</> </entry>
4317        <entry> rest of RE is an ERE </entry>
4318        </row>
4319
4320        <row>
4321        <entry> <literal>i</> </entry>
4322        <entry> case-insensitive matching (see
4323        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4324        </row>
4325
4326        <row>
4327        <entry> <literal>m</> </entry>
4328        <entry> historical synonym for <literal>n</> </entry>
4329        </row>
4330
4331        <row>
4332        <entry> <literal>n</> </entry>
4333        <entry> newline-sensitive matching (see
4334        <xref linkend="posix-matching-rules">) </entry>
4335        </row>
4336
4337        <row>
4338        <entry> <literal>p</> </entry>
4339        <entry> partial newline-sensitive matching (see
4340        <xref linkend="posix-matching-rules">) </entry>
4341        </row>
4342
4343        <row>
4344        <entry> <literal>q</> </entry>
4345        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4346        characters </entry>
4347        </row>
4348
4349        <row>
4350        <entry> <literal>s</> </entry>
4351        <entry> non-newline-sensitive matching (default) </entry>
4352        </row>
4353
4354        <row>
4355        <entry> <literal>t</> </entry>
4356        <entry> tight syntax (default; see below) </entry>
4357        </row>
4358
4359        <row>
4360        <entry> <literal>w</> </entry>
4361        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4362        (see <xref linkend="posix-matching-rules">) </entry>
4363        </row>
4364
4365        <row>
4366        <entry> <literal>x</> </entry>
4367        <entry> expanded syntax (see below) </entry>
4368        </row>
4369       </tbody>
4370      </tgroup>
4371     </table>
4372
4373    <para>
4374     Embedded options take effect at the <literal>)</> terminating the sequence.
4375     They can appear only at the start of an ARE (after the
4376     <literal>***:</> director if any).
4377    </para>
4378
4379    <para>
4380     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4381     characters are significant, there is an <firstterm>expanded</> syntax,
4382     available by specifying the embedded <literal>x</> option.
4383     In the expanded syntax,
4384     white-space characters in the RE are ignored, as are
4385     all characters between a <literal>#</>
4386     and the following newline (or the end of the RE).  This
4387     permits paragraphing and commenting a complex RE.
4388     There are three exceptions to that basic rule:
4389
4390     <itemizedlist>
4391      <listitem>
4392       <para>
4393        a white-space character or <literal>#</> preceded by <literal>\</> is
4394        retained
4395       </para>
4396      </listitem>
4397      <listitem>
4398       <para>
4399        white space or <literal>#</> within a bracket expression is retained
4400       </para>
4401      </listitem>
4402      <listitem>
4403       <para>
4404        white space and comments cannot appear within multi-character symbols,
4405        such as <literal>(?:</>
4406       </para>
4407      </listitem>
4408     </itemizedlist>
4409
4410     For this purpose, white-space characters are blank, tab, newline, and
4411     any character that belongs to the <replaceable>space</> character class.
4412    </para>
4413
4414    <para>
4415     Finally, in an ARE, outside bracket expressions, the sequence
4416     <literal>(?#</><replaceable>ttt</><literal>)</>
4417     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4418     is a comment, completely ignored.
4419     Again, this is not allowed between the characters of
4420     multi-character symbols, like <literal>(?:</>.
4421     Such comments are more a historical artifact than a useful facility,
4422     and their use is deprecated; use the expanded syntax instead.
4423    </para>
4424
4425    <para>
4426     <emphasis>None</> of these metasyntax extensions is available if
4427     an initial <literal>***=</> director
4428     has specified that the user's input be treated as a literal string
4429     rather than as an RE.
4430    </para>
4431    </sect3>
4432
4433    <sect3 id="posix-matching-rules">
4434     <title>Regular Expression Matching Rules</title>
4435
4436    <para>
4437     In the event that an RE could match more than one substring of a given
4438     string, the RE matches the one starting earliest in the string.
4439     If the RE could match more than one substring starting at that point,
4440     either the longest possible match or the shortest possible match will
4441     be taken, depending on whether the RE is <firstterm>greedy</> or
4442     <firstterm>non-greedy</>.
4443    </para>
4444
4445    <para>
4446     Whether an RE is greedy or not is determined by the following rules:
4447     <itemizedlist>
4448      <listitem>
4449       <para>
4450        Most atoms, and all constraints, have no greediness attribute (because
4451        they cannot match variable amounts of text anyway).
4452       </para>
4453      </listitem>
4454      <listitem>
4455       <para>
4456        Adding parentheses around an RE does not change its greediness.
4457       </para>
4458      </listitem>
4459      <listitem>
4460       <para>
4461        A quantified atom with a fixed-repetition quantifier
4462        (<literal>{</><replaceable>m</><literal>}</>
4463        or
4464        <literal>{</><replaceable>m</><literal>}?</>)
4465        has the same greediness (possibly none) as the atom itself.
4466       </para>
4467      </listitem>
4468      <listitem>
4469       <para>
4470        A quantified atom with other normal quantifiers (including
4471        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4472        with <replaceable>m</> equal to <replaceable>n</>)
4473        is greedy (prefers longest match).
4474       </para>
4475      </listitem>
4476      <listitem>
4477       <para>
4478        A quantified atom with a non-greedy quantifier (including
4479        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4480        with <replaceable>m</> equal to <replaceable>n</>)
4481        is non-greedy (prefers shortest match).
4482       </para>
4483      </listitem>
4484      <listitem>
4485       <para>
4486        A branch &mdash; that is, an RE that has no top-level
4487        <literal>|</> operator &mdash; has the same greediness as the first
4488        quantified atom in it that has a greediness attribute.
4489       </para>
4490      </listitem>
4491      <listitem>
4492       <para>
4493        An RE consisting of two or more branches connected by the
4494        <literal>|</> operator is always greedy.
4495       </para>
4496      </listitem>
4497     </itemizedlist>
4498    </para>
4499
4500    <para>
4501     The above rules associate greediness attributes not only with individual
4502     quantified atoms, but with branches and entire REs that contain quantified
4503     atoms.  What that means is that the matching is done in such a way that
4504     the branch, or whole RE, matches the longest or shortest possible
4505     substring <emphasis>as a whole</>.  Once the length of the entire match
4506     is determined, the part of it that matches any particular subexpression
4507     is determined on the basis of the greediness attribute of that
4508     subexpression, with subexpressions starting earlier in the RE taking
4509     priority over ones starting later.
4510    </para>
4511
4512    <para>
4513     An example of what this means:
4514 <screen>
4515 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4516 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4517 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4518 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4519 </screen>
4520     In the first case, the RE as a whole is greedy because <literal>Y*</>
4521     is greedy.  It can match beginning at the <literal>Y</>, and it matches
4522     the longest possible string starting there, i.e., <literal>Y123</>.
4523     The output is the parenthesized part of that, or <literal>123</>.
4524     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4525     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
4526     the shortest possible string starting there, i.e., <literal>Y1</>.
4527     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4528     the decision as to the overall match length; so it is forced to match
4529     just <literal>1</>.
4530    </para>
4531
4532    <para>
4533     In short, when an RE contains both greedy and non-greedy subexpressions,
4534     the total match length is either as long as possible or as short as
4535     possible, according to the attribute assigned to the whole RE.  The
4536     attributes assigned to the subexpressions only affect how much of that
4537     match they are allowed to <quote>eat</> relative to each other.
4538    </para>
4539
4540    <para>
4541     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4542     can be used to force greediness or non-greediness, respectively,
4543     on a subexpression or a whole RE.
4544    </para>
4545
4546    <para>
4547     Match lengths are measured in characters, not collating elements.
4548     An empty string is considered longer than no match at all.
4549     For example:
4550     <literal>bb*</>
4551     matches the three middle characters of <literal>abbbc</>;
4552     <literal>(week|wee)(night|knights)</>
4553     matches all ten characters of <literal>weeknights</>;
4554     when <literal>(.*).*</>
4555     is matched against <literal>abc</> the parenthesized subexpression
4556     matches all three characters; and when
4557     <literal>(a*)*</> is matched against <literal>bc</>
4558     both the whole RE and the parenthesized
4559     subexpression match an empty string.
4560    </para>
4561
4562    <para>
4563     If case-independent matching is specified,
4564     the effect is much as if all case distinctions had vanished from the
4565     alphabet.
4566     When an alphabetic that exists in multiple cases appears as an
4567     ordinary character outside a bracket expression, it is effectively
4568     transformed into a bracket expression containing both cases,
4569     e.g., <literal>x</> becomes <literal>[xX]</>.
4570     When it appears inside a bracket expression, all case counterparts
4571     of it are added to the bracket expression, e.g.,
4572     <literal>[x]</> becomes <literal>[xX]</>
4573     and <literal>[^x]</> becomes <literal>[^xX]</>.
4574    </para>
4575
4576    <para>
4577     If newline-sensitive matching is specified, <literal>.</>
4578     and bracket expressions using <literal>^</>
4579     will never match the newline character
4580     (so that matches will never cross newlines unless the RE
4581     explicitly arranges it)
4582     and <literal>^</>and <literal>$</>
4583     will match the empty string after and before a newline
4584     respectively, in addition to matching at beginning and end of string
4585     respectively.
4586     But the ARE escapes <literal>\A</> and <literal>\Z</>
4587     continue to match beginning or end of string <emphasis>only</>.
4588    </para>
4589
4590    <para>
4591     If partial newline-sensitive matching is specified,
4592     this affects <literal>.</> and bracket expressions
4593     as with newline-sensitive matching, but not <literal>^</>
4594     and <literal>$</>.
4595    </para>
4596
4597    <para>
4598     If inverse partial newline-sensitive matching is specified,
4599     this affects <literal>^</> and <literal>$</>
4600     as with newline-sensitive matching, but not <literal>.</>
4601     and bracket expressions.
4602     This isn't very useful but is provided for symmetry.
4603    </para>
4604    </sect3>
4605
4606    <sect3 id="posix-limits-compatibility">
4607     <title>Limits and Compatibility</title>
4608
4609    <para>
4610     No particular limit is imposed on the length of REs in this
4611     implementation.  However,
4612     programs intended to be highly portable should not employ REs longer
4613     than 256 bytes,
4614     as a POSIX-compliant implementation can refuse to accept such REs.
4615    </para>
4616
4617    <para>
4618     The only feature of AREs that is actually incompatible with
4619     POSIX EREs is that <literal>\</> does not lose its special
4620     significance inside bracket expressions.
4621     All other ARE features use syntax which is illegal or has
4622     undefined or unspecified effects in POSIX EREs;
4623     the <literal>***</> syntax of directors likewise is outside the POSIX
4624     syntax for both BREs and EREs.
4625    </para>
4626
4627    <para>
4628     Many of the ARE extensions are borrowed from Perl, but some have
4629     been changed to clean them up, and a few Perl extensions are not present.
4630     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
4631     the lack of special treatment for a trailing newline,
4632     the addition of complemented bracket expressions to the things
4633     affected by newline-sensitive matching,
4634     the restrictions on parentheses and back references in lookahead
4635     constraints, and the longest/shortest-match (rather than first-match)
4636     matching semantics.
4637    </para>
4638
4639    <para>
4640     Two significant incompatibilities exist between AREs and the ERE syntax
4641     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
4642
4643     <itemizedlist>
4644      <listitem>
4645       <para>
4646        In AREs, <literal>\</> followed by an alphanumeric character is either
4647        an escape or an error, while in previous releases, it was just another
4648        way of writing the alphanumeric.
4649        This should not be much of a problem because there was no reason to
4650        write such a sequence in earlier releases.
4651       </para>
4652      </listitem>
4653      <listitem>
4654       <para>
4655        In AREs, <literal>\</> remains a special character within
4656        <literal>[]</>, so a literal <literal>\</> within a bracket
4657        expression must be written <literal>\\</>.
4658       </para>
4659      </listitem>
4660     </itemizedlist>
4661
4662     While these differences are unlikely to create a problem for most
4663     applications, you can avoid them if necessary by
4664     setting <varname>regex_flavor</> to <literal>extended</>.
4665    </para>
4666    </sect3>
4667
4668    <sect3 id="posix-basic-regexes">
4669     <title>Basic Regular Expressions</title>
4670
4671    <para>
4672     BREs differ from EREs in several respects.
4673     In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
4674     are ordinary characters and there is no equivalent
4675     for their functionality.
4676     The delimiters for bounds are
4677     <literal>\{</> and <literal>\}</>,
4678     with <literal>{</> and <literal>}</>
4679     by themselves ordinary characters.
4680     The parentheses for nested subexpressions are
4681     <literal>\(</> and <literal>\)</>,
4682     with <literal>(</> and <literal>)</> by themselves ordinary characters.
4683     <literal>^</> is an ordinary character except at the beginning of the
4684     RE or the beginning of a parenthesized subexpression,
4685     <literal>$</> is an ordinary character except at the end of the
4686     RE or the end of a parenthesized subexpression,
4687     and <literal>*</> is an ordinary character if it appears at the beginning
4688     of the RE or the beginning of a parenthesized subexpression
4689     (after a possible leading <literal>^</>).
4690     Finally, single-digit back references are available, and
4691     <literal>\&lt;</> and <literal>\&gt;</>
4692     are synonyms for
4693     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
4694     respectively; no other escapes are available in BREs.
4695    </para>
4696    </sect3>
4697
4698 <!-- end re_syntax.n man page -->
4699
4700   </sect2>
4701  </sect1>
4702
4703
4704   <sect1 id="functions-formatting">
4705    <title>Data Type Formatting Functions</title>
4706
4707    <indexterm>
4708     <primary>formatting</primary>
4709    </indexterm>
4710
4711    <indexterm>
4712     <primary>to_char</primary>
4713    </indexterm>
4714    <indexterm>
4715     <primary>to_date</primary>
4716    </indexterm>
4717    <indexterm>
4718     <primary>to_number</primary>
4719    </indexterm>
4720    <indexterm>
4721     <primary>to_timestamp</primary>
4722    </indexterm>
4723
4724    <para>
4725     The <productname>PostgreSQL</productname> formatting functions
4726     provide a powerful set of tools for converting various data types
4727     (date/time, integer, floating point, numeric) to formatted strings
4728     and for converting from formatted strings to specific data types.
4729     <xref linkend="functions-formatting-table"> lists them.
4730     These functions all follow a common calling convention: the first
4731     argument is the value to be formatted and the second argument is a
4732     template that defines the output or input format.
4733    </para>
4734    <para>
4735     A single-argument <function>to_timestamp</function> function is also
4736     available;  it accepts a
4737     <type>double precision</type> argument and converts from Unix epoch
4738     (seconds since 1970-01-01 00:00:00+00) to
4739     <type>timestamp with time zone</type>.
4740     (<type>Integer</type> Unix epochs are implicitly cast to 
4741     <type>double precision</type>.)
4742    </para>
4743
4744     <table id="functions-formatting-table">
4745      <title>Formatting Functions</title>
4746      <tgroup cols="4">
4747       <thead>
4748        <row>
4749         <entry>Function</entry>
4750         <entry>Return Type</entry>
4751         <entry>Description</entry>
4752         <entry>Example</entry>
4753        </row>
4754       </thead>
4755       <tbody>
4756        <row>
4757         <entry><literal><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</literal></entry>
4758         <entry><type>text</type></entry>
4759         <entry>convert time stamp to string</entry>
4760         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
4761        </row>
4762        <row>
4763         <entry><literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal></entry>
4764         <entry><type>text</type></entry>
4765         <entry>convert interval to string</entry>
4766         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
4767        </row>
4768        <row>
4769         <entry><literal><function>to_char</function>(<type>int</type>, <type>text</type>)</literal></entry>
4770         <entry><type>text</type></entry>
4771         <entry>convert integer to string</entry>
4772         <entry><literal>to_char(125, '999')</literal></entry>
4773        </row>
4774        <row>
4775         <entry><literal><function>to_char</function>(<type>double precision</type>,
4776         <type>text</type>)</literal></entry>
4777         <entry><type>text</type></entry>
4778         <entry>convert real/double precision to string</entry>
4779         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
4780        </row>
4781        <row>
4782         <entry><literal><function>to_char</function>(<type>numeric</type>, <type>text</type>)</literal></entry>
4783         <entry><type>text</type></entry>
4784         <entry>convert numeric to string</entry>
4785         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
4786        </row>
4787        <row>
4788         <entry><literal><function>to_date</function>(<type>text</type>, <type>text</type>)</literal></entry>
4789         <entry><type>date</type></entry>
4790         <entry>convert string to date</entry>
4791         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4792        </row>
4793        <row>
4794         <entry><literal><function>to_number</function>(<type>text</type>, <type>text</type>)</literal></entry>
4795         <entry><type>numeric</type></entry>
4796         <entry>convert string to numeric</entry>
4797         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
4798        </row>
4799        <row>
4800         <entry><literal><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</literal></entry>
4801         <entry><type>timestamp with time zone</type></entry>
4802         <entry>convert string to time stamp</entry>
4803         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4804        </row>
4805        <row>
4806         <entry><literal><function>to_timestamp</function>(<type>double precision</type>)</literal></entry>
4807         <entry><type>timestamp with time zone</type></entry>
4808         <entry>convert UNIX epoch to time stamp</entry>
4809         <entry><literal>to_timestamp(1284352323)</literal></entry>
4810        </row>
4811       </tbody>
4812      </tgroup>
4813     </table>
4814
4815    <para>
4816     In a <function>to_char</> output template string, there are certain patterns that are
4817     recognized and replaced with appropriately-formatted data based on the value.
4818     Any text that is not a template pattern is simply
4819     copied verbatim.  Similarly, in an input template string (anything but <function>to_char</>), template patterns
4820     identify the values to be supplied by the input data string.
4821    </para>
4822
4823   <para>
4824    <xref linkend="functions-formatting-datetime-table"> shows the
4825    template patterns available for formatting date and time values.
4826   </para>
4827
4828     <table id="functions-formatting-datetime-table">
4829      <title>Template Patterns for Date/Time Formatting</title>
4830      <tgroup cols="2">
4831       <thead>
4832        <row>
4833         <entry>Pattern</entry>
4834         <entry>Description</entry>
4835        </row>
4836       </thead>
4837       <tbody>
4838        <row>
4839         <entry><literal>HH</literal></entry>
4840         <entry>hour of day (01-12)</entry>
4841        </row>
4842        <row>
4843         <entry><literal>HH12</literal></entry>
4844         <entry>hour of day (01-12)</entry>
4845        </row>       
4846        <row>
4847         <entry><literal>HH24</literal></entry>
4848         <entry>hour of day (00-23)</entry>
4849        </row>       
4850        <row>
4851         <entry><literal>MI</literal></entry>
4852         <entry>minute (00-59)</entry>
4853        </row>   
4854        <row>
4855         <entry><literal>SS</literal></entry>
4856         <entry>second (00-59)</entry>
4857        </row>
4858        <row>
4859         <entry><literal>MS</literal></entry>
4860         <entry>millisecond (000-999)</entry>
4861        </row>
4862        <row>
4863         <entry><literal>US</literal></entry>
4864         <entry>microsecond (000000-999999)</entry>
4865        </row>
4866        <row>
4867         <entry><literal>SSSS</literal></entry>
4868         <entry>seconds past midnight (0-86399)</entry>
4869        </row>
4870        <row>
4871         <entry><literal>AM</literal>, <literal>am</literal>,
4872         <literal>PM</literal> or <literal>pm</literal></entry>
4873         <entry>meridiem indicator (without periods)</entry>
4874        </row>
4875        <row>
4876         <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
4877         <literal>P.M.</literal> or <literal>p.m.</literal></entry>
4878         <entry>meridiem indicator (with periods)</entry>
4879        </row>
4880        <row>
4881         <entry><literal>Y,YYY</literal></entry>
4882         <entry>year (4 and more digits) with comma</entry>
4883        </row>
4884        <row>
4885         <entry><literal>YYYY</literal></entry>
4886         <entry>year (4 and more digits)</entry>
4887        </row>
4888        <row>
4889         <entry><literal>YYY</literal></entry>
4890         <entry>last 3 digits of year</entry>
4891        </row>
4892        <row>
4893         <entry><literal>YY</literal></entry>
4894         <entry>last 2 digits of year</entry>
4895        </row>
4896        <row>
4897         <entry><literal>Y</literal></entry>
4898         <entry>last digit of year</entry>
4899        </row>
4900        <row>
4901         <entry><literal>IYYY</literal></entry>
4902         <entry>ISO year (4 and more digits)</entry>
4903        </row>
4904        <row>
4905         <entry><literal>IYY</literal></entry>
4906         <entry>last 3 digits of ISO year</entry>
4907        </row>
4908        <row>
4909         <entry><literal>IY</literal></entry>
4910         <entry>last 2 digits of ISO year</entry>
4911        </row>
4912        <row>
4913         <entry><literal>I</literal></entry>
4914         <entry>last digit of ISO year</entry>
4915        </row>
4916        <row>
4917         <entry><literal>BC</literal>, <literal>bc</literal>,
4918         <literal>AD</literal> or <literal>ad</literal></entry>
4919         <entry>era indicator (without periods)</entry>
4920        </row>
4921        <row>
4922         <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
4923         <literal>A.D.</literal> or <literal>a.d.</literal></entry>
4924         <entry>era indicator (with periods)</entry>
4925        </row>
4926        <row>
4927         <entry><literal>MONTH</literal></entry>
4928         <entry>full uppercase month name (blank-padded to 9 chars)</entry>
4929        </row>
4930        <row>
4931         <entry><literal>Month</literal></entry>
4932         <entry>full capitalized month name (blank-padded to 9 chars)</entry>
4933        </row>
4934        <row>
4935         <entry><literal>month</literal></entry>
4936         <entry>full lowercase month name (blank-padded to 9 chars)</entry>
4937        </row>
4938        <row>
4939         <entry><literal>MON</literal></entry>
4940         <entry>abbreviated uppercase month name (3 chars in English, localized lengths vary)</entry>
4941        </row>
4942        <row>
4943         <entry><literal>Mon</literal></entry>
4944         <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
4945        </row>
4946        <row>
4947         <entry><literal>mon</literal></entry>
4948         <entry>abbreviated lowercase month name (3 chars in English, localized lengths vary)</entry>
4949        </row>
4950        <row>
4951         <entry><literal>MM</literal></entry>
4952         <entry>month number (01-12)</entry>
4953        </row>
4954        <row>
4955         <entry><literal>DAY</literal></entry>
4956         <entry>full uppercase day name (blank-padded to 9 chars)</entry>
4957        </row>
4958        <row>
4959         <entry><literal>Day</literal></entry>
4960         <entry>full capitalized day name (blank-padded to 9 chars)</entry>
4961        </row>
4962        <row>
4963         <entry><literal>day</literal></entry>
4964         <entry>full lowercase day name (blank-padded to 9 chars)</entry>
4965        </row>
4966        <row>
4967         <entry><literal>DY</literal></entry>
4968         <entry>abbreviated uppercase day name (3 chars in English, localized lengths vary)</entry>
4969        </row>
4970        <row>
4971         <entry><literal>Dy</literal></entry>
4972         <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
4973        </row>
4974        <row>
4975         <entry><literal>dy</literal></entry>
4976         <entry>abbreviated lowercase day name (3 chars in English, localized lengths vary)</entry>
4977        </row>
4978        <row>
4979         <entry><literal>DDD</literal></entry>
4980         <entry>day of year (001-366)</entry>
4981        </row>
4982        <row>
4983         <entry><literal>IDDD</literal></entry>
4984         <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
4985        </row>
4986        <row>
4987         <entry><literal>DD</literal></entry>
4988         <entry>day of month (01-31)</entry>
4989        </row>
4990        <row>
4991         <entry><literal>D</literal></entry>
4992         <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
4993        </row>
4994        <row>
4995         <entry><literal>ID</literal></entry>
4996         <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
4997        </row>
4998        <row>
4999         <entry><literal>W</literal></entry>
5000         <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
5001        </row> 
5002        <row>
5003         <entry><literal>WW</literal></entry>
5004         <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
5005        </row>
5006        <row>
5007         <entry><literal>IW</literal></entry>
5008         <entry>ISO week number of year (01 - 53; the first Thursday of the new year is in week 1.)</entry>
5009        </row>
5010        <row>
5011         <entry><literal>CC</literal></entry>
5012         <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
5013        </row>
5014        <row>
5015         <entry><literal>J</literal></entry>
5016         <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
5017        </row>
5018        <row>
5019         <entry><literal>Q</literal></entry>
5020         <entry>quarter</entry>
5021        </row>
5022        <row>
5023         <entry><literal>RM</literal></entry>
5024         <entry>uppercase month in Roman numerals (I-XII; I=January)</entry>
5025        </row>
5026        <row>
5027         <entry><literal>rm</literal></entry>
5028         <entry>lowercase month in Roman numerals (i-xii; i=January)</entry>
5029        </row>
5030        <row>
5031         <entry><literal>TZ</literal></entry>
5032         <entry>uppercase time-zone name</entry>
5033        </row>
5034        <row>
5035         <entry><literal>tz</literal></entry>
5036         <entry>lowercase time-zone name</entry>
5037        </row>
5038       </tbody>
5039      </tgroup>
5040     </table>
5041
5042    <para>
5043     Modifiers can be applied to any template pattern to alter its
5044     behavior.  For example, <literal>FMMonth</literal>
5045     is the <literal>Month</literal> pattern with the
5046     <literal>FM</literal> modifier.
5047     <xref linkend="functions-formatting-datetimemod-table"> shows the
5048     modifier patterns for date/time formatting.
5049    </para>
5050
5051     <table id="functions-formatting-datetimemod-table">
5052      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5053      <tgroup cols="3">
5054       <thead>
5055        <row>
5056         <entry>Modifier</entry>
5057         <entry>Description</entry>
5058         <entry>Example</entry>
5059        </row>
5060       </thead>
5061       <tbody>
5062        <row>
5063         <entry><literal>FM</literal> prefix</entry>
5064         <entry>fill mode (suppress padding of blanks and zeroes)</entry>
5065         <entry><literal>FMMonth</literal></entry>
5066        </row>
5067        <row>
5068         <entry><literal>TH</literal> suffix</entry>
5069         <entry>uppercase ordinal number suffix</entry>
5070         <entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
5071        </row>   
5072        <row>
5073         <entry><literal>th</literal> suffix</entry>
5074         <entry>lowercase ordinal number suffix</entry>
5075         <entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
5076        </row>
5077        <row>
5078         <entry><literal>FX</literal> prefix</entry>
5079         <entry>fixed format global option (see usage notes)</entry>
5080         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5081        </row>   
5082        <row>
5083         <entry><literal>TM</literal> prefix</entry>
5084         <entry>translation mode (print localized day and month names based on
5085          <xref linkend="guc-lc-time">)</entry>
5086         <entry><literal>TMMonth</literal></entry>
5087        </row>       
5088        <row>
5089         <entry><literal>SP</literal> suffix</entry>
5090         <entry>spell mode (not supported)</entry>
5091         <entry><literal>DDSP</literal></entry>
5092        </row>       
5093       </tbody>
5094      </tgroup>
5095     </table>
5096
5097    <para>
5098     Usage notes for date/time formatting:
5099
5100     <itemizedlist>
5101      <listitem>
5102       <para>
5103        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5104        that would otherwise be added to make the output of a pattern be
5105        fixed-width.
5106       </para>
5107      </listitem>
5108
5109      <listitem>
5110       <para>
5111        <literal>TM</literal> does not include trailing blanks.
5112       </para>
5113      </listitem>
5114
5115      <listitem>
5116       <para>
5117        <function>to_timestamp</function> and <function>to_date</function>
5118        skip multiple blank spaces in the input string unless the <literal>FX</literal> option 
5119        is used. For example,
5120        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> works, but
5121        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
5122        because <function>to_timestamp</function> expects one space only.
5123        <literal>FX</literal> must be specified as the first item in
5124        the template.
5125       </para>
5126      </listitem>
5127
5128      <listitem>
5129       <para>
5130        Ordinary text is allowed in <function>to_char</function>
5131        templates and will be output literally.  You can put a substring
5132        in double quotes to force it to be interpreted as literal text
5133        even if it contains pattern key words.  For example, in
5134        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5135        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5136        will not be.
5137       </para>
5138      </listitem>
5139
5140      <listitem>
5141       <para>
5142        If you want to have a double quote in the output you must
5143        precede it with a backslash, for example <literal>E'\\"YYYY
5144        Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
5145        (Two backslashes are necessary because the backslash
5146        has special meaning when using the escape string syntax.)
5147       </para>
5148      </listitem>
5149
5150      <listitem>
5151       <para>
5152        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5153        <type>date</type> has a restriction when processing years with more than 4 digits. You must
5154        use some non-digit character or template after <literal>YYYY</literal>,
5155        otherwise the year is always interpreted as 4 digits. For example
5156        (with the year 20000):
5157        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
5158        interpreted as a 4-digit year; instead use a non-digit 
5159        separator after the year, like
5160        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5161        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5162       </para>
5163      </listitem>
5164
5165      <listitem>
5166       <para>
5167        In conversions from string to <type>timestamp</type> or
5168        <type>date</type>, the <literal>CC</literal> field (century) is ignored if there
5169        is a <literal>YYY</literal>, <literal>YYYY</literal> or
5170        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5171        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5172        as <literal>(CC-1)*100+YY</literal>.
5173       </para>
5174      </listitem>
5175
5176      <listitem>
5177       <para>
5178        An ISO week date (as distinct from a Gregorian date) can be
5179        specified to <function>to_timestamp</function> and
5180        <function>to_date</function> in one of two ways:
5181        <itemizedlist>
5182         <listitem>
5183          <para>
5184           Year, week, and weekday:  for example <literal>to_date('2006-42-4',
5185           'IYYY-IW-ID')</literal> returns the date
5186           <literal>2006-10-19</literal>.  If you omit the weekday it
5187           is assumed to be 1 (Monday).
5188          </para>
5189         </listitem>
5190         <listitem>
5191          <para>
5192           Year and day of year:  for example <literal>to_date('2006-291',
5193           'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5194          </para>
5195         </listitem>
5196        </itemizedlist>
5197       </para>
5198       <para>
5199        Attempting to construct a date using a mixture of ISO week and
5200        Gregorian date fields is nonsensical, and will cause an error.  In the
5201        context of an ISO year, the concept of a <quote>month</> or <quote>day
5202        of month</> has no meaning.  In the context of a Gregorian year, the
5203        ISO week has no meaning.  Users should avoid mixing Gregorian and
5204        ISO date specifications.
5205       </para>
5206      </listitem>
5207
5208      <listitem>
5209       <para>
5210        In a conversion from string to <type>timestamp</type>, millisecond
5211        (<literal>MS</literal>) and microsecond (<literal>US</literal>)
5212        values are used as the
5213        seconds digits after the decimal point. For example 
5214        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5215        but 300, because the conversion counts it as 12 + 0.3 seconds.
5216        This means for the format <literal>SS:MS</literal>, the input values
5217        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5218        same number of milliseconds. To get three milliseconds, one must use
5219        <literal>12:003</literal>, which the conversion counts as
5220        12 + 0.003 = 12.003 seconds.
5221       </para>
5222
5223       <para>
5224        Here is a more 
5225        complex example: 
5226        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5227        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5228        1230 microseconds = 2.021230 seconds. 
5229       </para>
5230      </listitem>
5231
5232      <listitem>
5233       <para>
5234         <function>to_char(..., 'ID')</function>'s day of the week numbering
5235         matches the <function>extract('isodow', ...)</function> function, but
5236         <function>to_char(..., 'D')</function>'s does not match
5237         <function>extract('dow', ...)</function>'s day numbering.
5238       </para>
5239      </listitem>
5240
5241      <listitem>
5242       <para><function>to_char(interval)</function> formats <literal>HH</> and 
5243         <literal>HH12</> as hours in a single day, while <literal>HH24</>
5244         can output hours exceeding a single day, e.g., &gt;24.
5245       </para>
5246      </listitem>
5247
5248     </itemizedlist>
5249    </para>
5250
5251   <para>
5252    <xref linkend="functions-formatting-numeric-table"> shows the
5253    template patterns available for formatting numeric values.
5254   </para>
5255
5256     <table id="functions-formatting-numeric-table">
5257      <title>Template Patterns for Numeric Formatting</title>
5258      <tgroup cols="2">
5259       <thead>
5260        <row>
5261         <entry>Pattern</entry>
5262         <entry>Description</entry>
5263        </row>
5264       </thead>
5265       <tbody>
5266        <row>
5267         <entry><literal>9</literal></entry>
5268         <entry>value with the specified number of digits</entry>
5269        </row>
5270        <row>
5271         <entry><literal>0</literal></entry>
5272         <entry>value with leading zeros</entry>
5273        </row>
5274        <row>
5275         <entry><literal>.</literal> (period)</entry>
5276         <entry>decimal point</entry>
5277        </row>       
5278        <row>
5279         <entry><literal>,</literal> (comma)</entry>
5280         <entry>group (thousand) separator</entry>
5281        </row>
5282        <row>
5283         <entry><literal>PR</literal></entry>
5284         <entry>negative value in angle brackets</entry>
5285        </row>
5286        <row>
5287         <entry><literal>S</literal></entry>
5288         <entry>sign anchored to number (uses locale)</entry>
5289        </row>
5290        <row>
5291         <entry><literal>L</literal></entry>
5292         <entry>currency symbol (uses locale)</entry>
5293        </row>
5294        <row>
5295         <entry><literal>D</literal></entry>
5296         <entry>decimal point (uses locale)</entry>
5297        </row>
5298        <row>
5299         <entry><literal>G</literal></entry>
5300         <entry>group separator (uses locale)</entry>
5301        </row>
5302        <row>
5303         <entry><literal>MI</literal></entry>
5304         <entry>minus sign in specified position (if number &lt; 0)</entry>
5305        </row>
5306        <row>
5307         <entry><literal>PL</literal></entry>
5308         <entry>plus sign in specified position (if number &gt; 0)</entry>
5309        </row>
5310        <row>
5311         <entry><literal>SG</literal></entry>
5312         <entry>plus/minus sign in specified position</entry>
5313        </row>
5314        <row>
5315         <entry><literal>RN</literal></entry>
5316         <entry>Roman numeral (input between 1 and 3999)</entry>
5317        </row>
5318        <row>
5319         <entry><literal>TH</literal> or <literal>th</literal></entry>
5320         <entry>ordinal number suffix</entry>
5321        </row>
5322        <row>
5323         <entry><literal>V</literal></entry>
5324         <entry>shift specified number of digits (see notes)</entry>
5325        </row>
5326        <row>
5327         <entry><literal>EEEE</literal></entry>
5328         <entry>scientific notation (not implemented)</entry>
5329        </row>
5330       </tbody>
5331      </tgroup>
5332     </table>
5333
5334    <para>
5335     Usage notes for numeric formatting:
5336
5337     <itemizedlist>
5338      <listitem>
5339       <para>
5340        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5341        <literal>MI</literal> is not anchored to
5342        the number; for example,
5343        <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
5344        but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
5345        The Oracle implementation does not allow the use of
5346        <literal>MI</literal> before <literal>9</literal>, but rather
5347        requires that <literal>9</literal> precede
5348        <literal>MI</literal>.
5349       </para>
5350      </listitem>
5351
5352      <listitem>
5353       <para>
5354        <literal>9</literal> results in a value with the same number of 
5355        digits as there are <literal>9</literal>s. If a digit is
5356        not available it outputs a space.
5357       </para>
5358      </listitem>
5359
5360      <listitem>
5361       <para>
5362        <literal>TH</literal> does not convert values less than zero
5363        and does not convert fractional numbers.
5364       </para>
5365      </listitem>
5366
5367      <listitem>
5368       <para>
5369        <literal>PL</literal>, <literal>SG</literal>, and
5370        <literal>TH</literal> are <productname>PostgreSQL</productname>
5371        extensions. 
5372       </para>
5373      </listitem>
5374
5375      <listitem>
5376       <para>
5377        <literal>V</literal> effectively
5378        multiplies the input values by
5379        <literal>10^<replaceable>n</replaceable></literal>, where
5380        <replaceable>n</replaceable> is the number of digits following
5381        <literal>V</literal>. 
5382        <function>to_char</function> does not support the use of
5383        <literal>V</literal> with non-integer values.
5384        (e.g., <literal>99.9V99</literal> is not allowed.)
5385       </para>
5386      </listitem>
5387     </itemizedlist>
5388    </para>   
5389
5390    <para>
5391     Certain modifiers can be applied to any template pattern to alter its
5392     behavior.  For example, <literal>FM9999</literal>
5393     is the <literal>9999</literal> pattern with the
5394     <literal>FM</literal> modifier.
5395     <xref linkend="functions-formatting-numericmod-table"> shows the
5396     modifier patterns for numeric formatting.
5397    </para>
5398
5399     <table id="functions-formatting-numericmod-table">
5400      <title>Template Pattern Modifiers for Numeric Formatting</title>
5401      <tgroup cols="3">
5402       <thead>
5403        <row>
5404         <entry>Modifier</entry>
5405         <entry>Description</entry>
5406         <entry>Example</entry>
5407        </row>
5408       </thead>
5409       <tbody>
5410        <row>
5411         <entry><literal>FM</literal> prefix</entry>
5412         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5413         <entry><literal>FM9999</literal></entry>
5414        </row>
5415        <row>
5416         <entry><literal>TH</literal> suffix</entry>
5417         <entry>uppercase ordinal number suffix</entry>
5418         <entry><literal>999TH</literal></entry>
5419        </row>   
5420        <row>
5421         <entry><literal>th</literal> suffix</entry>
5422         <entry>lowercase ordinal number suffix</entry>
5423         <entry><literal>999th</literal></entry>
5424        </row>
5425       </tbody>
5426      </tgroup>
5427     </table>
5428
5429   <para>
5430    <xref linkend="functions-formatting-examples-table"> shows some
5431    examples of the use of the <function>to_char</function> function.
5432   </para>
5433
5434     <table id="functions-formatting-examples-table">
5435      <title><function>to_char</function> Examples</title>
5436      <tgroup cols="2">
5437       <thead>
5438        <row>
5439         <entry>Expression</entry>
5440         <entry>Result</entry>
5441        </row>
5442       </thead>
5443       <tbody>
5444        <row>
5445         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5446         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
5447        </row>
5448        <row>
5449         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5450         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
5451        </row>          
5452        <row>
5453         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5454         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
5455        </row>
5456        <row>
5457         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5458         <entry><literal>'-.1'</literal></entry>
5459        </row>
5460        <row>
5461         <entry><literal>to_char(0.1, '0.9')</literal></entry>
5462         <entry><literal>'&nbsp;0.1'</literal></entry>
5463        </row>
5464        <row>
5465         <entry><literal>to_char(12, '9990999.9')</literal></entry>
5466         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
5467        </row>
5468        <row>
5469         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5470         <entry><literal>'0012.'</literal></entry>
5471        </row>
5472        <row>
5473         <entry><literal>to_char(485, '999')</literal></entry>
5474         <entry><literal>'&nbsp;485'</literal></entry>
5475        </row>
5476        <row>
5477         <entry><literal>to_char(-485, '999')</literal></entry>
5478         <entry><literal>'-485'</literal></entry>
5479        </row>
5480        <row>
5481         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
5482         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
5483        </row>
5484        <row>
5485         <entry><literal>to_char(1485, '9,999')</literal></entry>
5486         <entry><literal>'&nbsp;1,485'</literal></entry>
5487        </row>
5488        <row>
5489         <entry><literal>to_char(1485, '9G999')</literal></entry>
5490         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
5491        </row>
5492        <row>
5493         <entry><literal>to_char(148.5, '999.999')</literal></entry>
5494         <entry><literal>'&nbsp;148.500'</literal></entry>
5495        </row>
5496        <row>
5497         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5498         <entry><literal>'148.5'</literal></entry>
5499        </row>
5500        <row>
5501         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5502         <entry><literal>'148.500'</literal></entry>
5503        </row>
5504        <row>
5505         <entry><literal>to_char(148.5, '999D999')</literal></entry>
5506         <entry><literal>'&nbsp;148,500'</literal></entry>        
5507        </row>
5508        <row>
5509         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5510         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
5511        </row>
5512        <row>
5513         <entry><literal>to_char(-485, '999S')</literal></entry>
5514         <entry><literal>'485-'</literal></entry>
5515        </row>
5516        <row>            
5517         <entry><literal>to_char(-485, '999MI')</literal></entry>
5518         <entry><literal>'485-'</literal></entry>        
5519        </row>
5520        <row>
5521         <entry><literal>to_char(485, '999MI')</literal></entry>
5522         <entry><literal>'485&nbsp;'</literal></entry>           
5523        </row>
5524        <row>
5525         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5526         <entry><literal>'485'</literal></entry>         
5527        </row>
5528        <row>
5529         <entry><literal>to_char(485, 'PL999')</literal></entry>
5530         <entry><literal>'+485'</literal></entry>        
5531        </row>
5532        <row>            
5533         <entry><literal>to_char(485, 'SG999')</literal></entry>
5534         <entry><literal>'+485'</literal></entry>        
5535        </row>
5536        <row>
5537         <entry><literal>to_char(-485, 'SG999')</literal></entry>
5538         <entry><literal>'-485'</literal></entry>        
5539        </row>
5540        <row>
5541         <entry><literal>to_char(-485, '9SG99')</literal></entry>
5542         <entry><literal>'4-85'</literal></entry>        
5543        </row>
5544        <row>
5545         <entry><literal>to_char(-485, '999PR')</literal></entry>
5546         <entry><literal>'&lt;485&gt;'</literal></entry>         
5547        </row>
5548        <row>
5549         <entry><literal>to_char(485, 'L999')</literal></entry>
5550         <entry><literal>'DM&nbsp;485</literal></entry>   
5551        </row>
5552        <row>
5553         <entry><literal>to_char(485, 'RN')</literal></entry>            
5554         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
5555        </row>
5556        <row>
5557         <entry><literal>to_char(485, 'FMRN')</literal></entry>  
5558         <entry><literal>'CDLXXXV'</literal></entry>
5559        </row>
5560        <row>
5561         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5562         <entry><literal>'V'</literal></entry>           
5563        </row>
5564        <row>
5565         <entry><literal>to_char(482, '999th')</literal></entry>
5566         <entry><literal>'&nbsp;482nd'</literal></entry>                         
5567        </row>
5568        <row>
5569         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
5570         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
5571        </row>
5572        <row>
5573         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
5574         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
5575        </row>
5576        <row>
5577         <entry><literal>to_char(12, '99V999')</literal></entry>         
5578         <entry><literal>'&nbsp;12000'</literal></entry>
5579        </row>
5580        <row>
5581         <entry><literal>to_char(12.4, '99V999')</literal></entry>
5582         <entry><literal>'&nbsp;12400'</literal></entry>
5583        </row>
5584        <row>            
5585         <entry><literal>to_char(12.45, '99V9')</literal></entry>
5586         <entry><literal>'&nbsp;125'</literal></entry>
5587        </row>
5588       </tbody>
5589      </tgroup>
5590     </table>
5591
5592   </sect1>
5593
5594
5595   <sect1 id="functions-datetime">
5596    <title>Date/Time Functions and Operators</title>
5597
5598   <para>
5599    <xref linkend="functions-datetime-table"> shows the available
5600    functions for date/time value processing, with details appearing in
5601    the following subsections.  <xref
5602    linkend="operators-datetime-table"> illustrates the behaviors of
5603    the basic arithmetic operators (<literal>+</literal>,
5604    <literal>*</literal>, etc.).  For formatting functions, refer to
5605    <xref linkend="functions-formatting">.  You should be familiar with
5606    the background information on date/time data types from <xref
5607    linkend="datatype-datetime">.
5608   </para>
5609
5610   <para>
5611    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
5612    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
5613    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
5614    For brevity, these variants are not shown separately.  Also, the
5615    <literal>+</> and <literal>*</> operators come in commutative pairs (for
5616    example both date + integer and integer + date); we show only one of each
5617    such pair.
5618   </para>
5619
5620     <table id="operators-datetime-table">
5621      <title>Date/Time Operators</title>
5622
5623      <tgroup cols="3">
5624       <thead>
5625        <row>
5626         <entry>Operator</entry>
5627         <entry>Example</entry>
5628         <entry>Result</entry>
5629        </row>
5630       </thead>
5631
5632       <tbody>
5633        <row>
5634         <entry> <literal>+</literal> </entry>
5635         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
5636         <entry><literal>date '2001-10-05'</literal></entry>
5637        </row>
5638
5639        <row>
5640         <entry> <literal>+</literal> </entry>
5641         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
5642         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
5643        </row>
5644
5645        <row>
5646         <entry> <literal>+</literal> </entry>
5647         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
5648         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
5649        </row>
5650
5651        <row>
5652         <entry> <literal>+</literal> </entry>
5653         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
5654         <entry><literal>interval '1 day 01:00:00'</literal></entry>
5655        </row>
5656
5657        <row>
5658         <entry> <literal>+</literal> </entry>
5659         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
5660         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
5661        </row>
5662
5663        <row>
5664         <entry> <literal>+</literal> </entry>
5665         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
5666         <entry><literal>time '04:00:00'</literal></entry>
5667        </row>
5668
5669        <row>
5670         <entry> <literal>-</literal> </entry>
5671         <entry><literal>- interval '23 hours'</literal></entry>
5672         <entry><literal>interval '-23:00:00'</literal></entry>
5673        </row>
5674
5675        <row>
5676         <entry> <literal>-</literal> </entry>
5677         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
5678         <entry><literal>integer '3'</literal> (days)</entry>
5679        </row>
5680
5681        <row>
5682         <entry> <literal>-</literal> </entry>
5683         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
5684         <entry><literal>date '2001-09-24'</literal></entry>
5685        </row>
5686
5687        <row>
5688         <entry> <literal>-</literal> </entry>
5689         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
5690         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
5691        </row>
5692
5693        <row>
5694         <entry> <literal>-</literal> </entry>
5695         <entry><literal>time '05:00' - time '03:00'</literal></entry>
5696         <entry><literal>interval '02:00:00'</literal></entry>
5697        </row>
5698
5699        <row>
5700         <entry> <literal>-</literal> </entry>
5701         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
5702         <entry><literal>time '03:00:00'</literal></entry>
5703        </row>
5704
5705        <row>
5706         <entry> <literal>-</literal> </entry>
5707         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
5708         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
5709        </row>
5710
5711        <row>
5712         <entry> <literal>-</literal> </entry>
5713         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
5714         <entry><literal>interval '1 day -01:00:00'</literal></entry>
5715        </row>
5716
5717        <row>
5718         <entry> <literal>-</literal> </entry>
5719         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
5720         <entry><literal>interval '1 day 15:00:00'</literal></entry>
5721        </row>
5722
5723        <row>
5724         <entry> <literal>*</literal> </entry>
5725         <entry><literal>900 * interval '1 second'</literal></entry>
5726         <entry><literal>interval '00:15:00'</literal></entry>
5727        </row>
5728
5729        <row>
5730         <entry> <literal>*</literal> </entry>
5731         <entry><literal>21 * interval '1 day'</literal></entry>
5732         <entry><literal>interval '21 days'</literal></entry>
5733        </row>
5734
5735        <row>
5736         <entry> <literal>*</literal> </entry>
5737         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
5738         <entry><literal>interval '03:30:00'</literal></entry>
5739        </row>
5740
5741        <row>
5742         <entry> <literal>/</literal> </entry>
5743         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
5744         <entry><literal>interval '00:40:00'</literal></entry>
5745        </row>
5746       </tbody>
5747      </tgroup>
5748     </table>
5749
5750    <indexterm>
5751     <primary>age</primary>
5752    </indexterm>
5753    <indexterm>
5754     <primary>clock_timestamp</primary>
5755    </indexterm>
5756    <indexterm>
5757     <primary>current_date</primary>
5758    </indexterm>
5759    <indexterm>
5760     <primary>current_time</primary>
5761    </indexterm>
5762    <indexterm>
5763     <primary>current_timestamp</primary>
5764    </indexterm>
5765    <indexterm>
5766     <primary>date_part</primary>
5767    </indexterm>
5768    <indexterm>
5769     <primary>date_trunc</primary>
5770    </indexterm>
5771    <indexterm>
5772     <primary>extract</primary>
5773    </indexterm>
5774    <indexterm>
5775     <primary>isfinite</primary>
5776    </indexterm>
5777    <indexterm>
5778     <primary>justify_days</primary>
5779    </indexterm>
5780    <indexterm>
5781     <primary>justify_hours</primary>
5782    </indexterm>
5783    <indexterm>
5784     <primary>justify_interval</primary>
5785    </indexterm>
5786    <indexterm>
5787     <primary>localtime</primary>
5788    </indexterm>
5789    <indexterm>
5790     <primary>localtimestamp</primary>
5791    </indexterm>
5792    <indexterm>
5793     <primary>now</primary>
5794    </indexterm>
5795    <indexterm>
5796     <primary>statement_timestamp</primary>
5797    </indexterm>
5798    <indexterm>
5799     <primary>timeofday</primary>
5800    </indexterm>
5801    <indexterm>
5802     <primary>transaction_timestamp</primary>
5803    </indexterm>
5804
5805     <table id="functions-datetime-table">
5806      <title>Date/Time Functions</title>
5807      <tgroup cols="5">
5808       <thead>
5809        <row>
5810         <entry>Function</entry>
5811         <entry>Return Type</entry>
5812         <entry>Description</entry>
5813         <entry>Example</entry>
5814         <entry>Result</entry>
5815        </row>
5816       </thead>
5817
5818       <tbody>
5819        <row>
5820         <entry><literal><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</literal></entry>
5821         <entry><type>interval</type></entry>
5822         <entry>Subtract arguments, producing a <quote>symbolic</> result that
5823         uses years and months</entry>
5824         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
5825         <entry><literal>43 years 9 mons 27 days</literal></entry>
5826        </row>
5827
5828        <row>
5829         <entry><literal><function>age</function>(<type>timestamp</type>)</literal></entry>
5830         <entry><type>interval</type></entry>
5831         <entry>Subtract from <function>current_date</function> (at midnight)</entry>
5832         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
5833         <entry><literal>43 years 8 mons 3 days</literal></entry>
5834        </row>
5835
5836        <row>
5837         <entry><literal><function>clock_timestamp</function>()</literal></entry>
5838         <entry><type>timestamp with time zone</type></entry>
5839         <entry>Current date and time (changes during statement execution);
5840          see <xref linkend="functions-datetime-current">
5841         </entry>
5842         <entry></entry>
5843         <entry></entry>
5844        </row>
5845
5846        <row>
5847         <entry><literal><function>current_date</function></literal></entry>
5848         <entry><type>date</type></entry>
5849         <entry>Current date;
5850          see <xref linkend="functions-datetime-current">
5851         </entry>
5852         <entry></entry>
5853         <entry></entry>
5854        </row>
5855
5856        <row>
5857         <entry><literal><function>current_time</function></literal></entry>
5858         <entry><type>time with time zone</type></entry>
5859         <entry>Current time of day;
5860          see <xref linkend="functions-datetime-current">
5861         </entry>
5862         <entry></entry>
5863         <entry></entry>
5864        </row>
5865
5866        <row>
5867         <entry><literal><function>current_timestamp</function></literal></entry>
5868         <entry><type>timestamp with time zone</type></entry>
5869         <entry>Current date and time (start of current transaction);
5870          see <xref linkend="functions-datetime-current">
5871         </entry>
5872         <entry></entry>
5873         <entry></entry>
5874        </row>
5875
5876        <row>
5877         <entry><literal><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5878         <entry><type>double precision</type></entry>
5879         <entry>Get subfield (equivalent to <function>extract</function>);
5880          see <xref linkend="functions-datetime-extract">
5881         </entry>
5882         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5883         <entry><literal>20</literal></entry>
5884        </row>
5885
5886        <row>
5887         <entry><literal><function>date_part</function>(<type>text</type>, <type>interval</type>)</literal></entry>
5888         <entry><type>double precision</type></entry>
5889         <entry>Get subfield (equivalent to
5890          <function>extract</function>); see <xref linkend="functions-datetime-extract">
5891         </entry>
5892         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
5893         <entry><literal>3</literal></entry>
5894        </row>
5895
5896        <row>
5897         <entry><literal><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5898         <entry><type>timestamp</type></entry>
5899         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
5900         </entry>
5901         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5902         <entry><literal>2001-02-16 20:00:00</literal></entry>
5903        </row>
5904
5905        <row>
5906         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5907          <type>timestamp</type>)</literal></entry>
5908         <entry><type>double precision</type></entry>
5909         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5910         </entry>
5911         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
5912         <entry><literal>20</literal></entry>
5913        </row>
5914
5915        <row>
5916         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5917          <type>interval</type>)</literal></entry>
5918         <entry><type>double precision</type></entry>
5919         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5920         </entry>
5921         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
5922         <entry><literal>3</literal></entry>
5923        </row>
5924
5925        <row>
5926         <entry><literal><function>isfinite</function>(<type>date</type>)</literal></entry>
5927         <entry><type>boolean</type></entry>
5928         <entry>Test for finite date (not +/-infinity)</entry>
5929         <entry><literal>isfinite(date '2001-02-16')</literal></entry>
5930         <entry><literal>true</literal></entry>
5931        </row>
5932
5933        <row>
5934         <entry><literal><function>isfinite</function>(<type>timestamp</type>)</literal></entry>
5935         <entry><type>boolean</type></entry>
5936         <entry>Test for finite time stamp (not +/-infinity)</entry>
5937         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
5938         <entry><literal>true</literal></entry>
5939        </row>
5940
5941        <row>
5942         <entry><literal><function>isfinite</function>(<type>interval</type>)</literal></entry>
5943         <entry><type>boolean</type></entry>
5944         <entry>Test for finite interval</entry>
5945         <entry><literal>isfinite(interval '4 hours')</literal></entry>
5946         <entry><literal>true</literal></entry>
5947        </row>
5948
5949        <row>
5950         <entry><literal><function>justify_days</function>(<type>interval</type>)</literal></entry>
5951         <entry><type>interval</type></entry>
5952         <entry>Adjust interval so 30-day time periods are represented as months</entry>
5953         <entry><literal>justify_days(interval '35 days')</literal></entry>
5954         <entry><literal>1 mon 5 days</literal></entry>
5955        </row>
5956
5957        <row>
5958         <entry><literal><function>justify_hours</function>(<type>interval</type>)</literal></entry>
5959         <entry><type>interval</type></entry>
5960         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
5961         <entry><literal>justify_hours(interval '27 hours')</literal></entry>
5962         <entry><literal>1 day 03:00:00</literal></entry>
5963        </row>
5964
5965        <row>
5966         <entry><literal><function>justify_interval</function>(<type>interval</type>)</literal></entry>
5967         <entry><type>interval</type></entry>
5968         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
5969         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
5970         <entry><literal>29 days 23:00:00</literal></entry>
5971        </row>
5972
5973        <row>
5974         <entry><literal><function>localtime</function></literal></entry>
5975         <entry><type>time</type></entry>
5976         <entry>Current time of day;
5977          see <xref linkend="functions-datetime-current">
5978         </entry>
5979         <entry></entry>
5980         <entry></entry>
5981        </row>
5982
5983        <row>
5984         <entry><literal><function>localtimestamp</function></literal></entry>
5985         <entry><type>timestamp</type></entry>
5986         <entry>Current date and time (start of current transaction);
5987          see <xref linkend="functions-datetime-current">
5988         </entry>
5989         <entry></entry>
5990         <entry></entry>
5991        </row>
5992
5993        <row>
5994         <entry><literal><function>now</function>()</literal></entry>
5995         <entry><type>timestamp with time zone</type></entry>
5996         <entry>Current date and time (start of current transaction);
5997          see <xref linkend="functions-datetime-current">
5998         </entry>
5999         <entry></entry>
6000         <entry></entry>
6001        </row>
6002
6003        <row>
6004         <entry><literal><function>statement_timestamp</function>()</literal></entry>
6005         <entry><type>timestamp with time zone</type></entry>
6006         <entry>Current date and time (start of current statement);
6007          see <xref linkend="functions-datetime-current">
6008         </entry>
6009         <entry></entry>
6010         <entry></entry>
6011        </row>
6012
6013        <row>
6014         <entry><literal><function>timeofday</function>()</literal></entry>
6015         <entry><type>text</type></entry>
6016         <entry>Current date and time
6017          (like <function>clock_timestamp</>, but as a <type>text</> string);
6018          see <xref linkend="functions-datetime-current">
6019         </entry>
6020         <entry></entry>
6021         <entry></entry>
6022        </row>
6023
6024        <row>
6025         <entry><literal><function>transaction_timestamp</function>()</literal></entry>
6026         <entry><type>timestamp with time zone</type></entry>
6027         <entry>Current date and time (start of current transaction);
6028          see <xref linkend="functions-datetime-current">
6029         </entry>
6030         <entry></entry>
6031         <entry></entry>
6032        </row>
6033       </tbody>
6034      </tgroup>
6035     </table>
6036
6037    <para>
6038     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6039     supported:
6040 <synopsis>
6041 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6042 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6043 </synopsis>
6044     This expression yields true when two time periods (defined by their
6045     endpoints) overlap, false when they do not overlap.  The endpoints
6046     can be specified as pairs of dates, times, or time stamps; or as
6047     a date, time, or time stamp followed by an interval.
6048    </para>
6049
6050 <screen>
6051 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6052        (DATE '2001-10-30', DATE '2002-10-30');
6053 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6054 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6055        (DATE '2001-10-30', DATE '2002-10-30');
6056 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6057 </screen>
6058
6059   <para>
6060    When adding an <type>interval</type> value to (or subtracting an 
6061    <type>interval</type> value from) a <type>timestamp with time zone</type> 
6062    value, the days component advances (or decrements) the date of the 
6063    <type>timestamp with time zone</type> by the indicated number of days. 
6064    Across daylight saving time changes (with the session time zone set to a 
6065    time zone that recognizes DST), this means <literal>interval '1 day'</literal> 
6066    does not necessarily equal <literal>interval '24 hours'</literal>. 
6067    For example, with the session time zone set to <literal>CST7CDT</literal>,
6068    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
6069    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>, 
6070    while adding <literal>interval '24 hours'</literal> to the same initial 
6071    <type>timestamp with time zone</type> produces
6072    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6073    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone 
6074    <literal>CST7CDT</literal>.
6075   </para>
6076
6077   <para>
6078    Note there can be ambiguity in the <literal>months</> returned by
6079    <function>age</> because different months have a different number of
6080    days.  <productname>PostgreSQL</>'s approach uses the month from the
6081    earlier of the two dates when calculating partial months.  For example,
6082    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6083    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6084    days</> because May has 31 days, while April has only 30.
6085   </para>
6086
6087   <sect2 id="functions-datetime-extract">
6088    <title><function>EXTRACT</function>, <function>date_part</function></title>
6089
6090    <indexterm>
6091     <primary>date_part</primary>
6092    </indexterm>
6093    <indexterm>
6094     <primary>extract</primary>
6095    </indexterm>
6096
6097 <synopsis>
6098 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6099 </synopsis>
6100
6101    <para>
6102     The <function>extract</function> function retrieves subfields
6103     such as year or hour from date/time values.
6104     <replaceable>source</replaceable> must be a value expression of
6105     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6106     (Expressions of type <type>date</type> are
6107     cast to <type>timestamp</type> and can therefore be used as
6108     well.)  <replaceable>field</replaceable> is an identifier or
6109     string that selects what field to extract from the source value.
6110     The <function>extract</function> function returns values of type
6111     <type>double precision</type>.
6112     The following are valid field names:
6113
6114     <!-- alphabetical -->
6115     <variablelist>
6116      <varlistentry>
6117       <term><literal>century</literal></term>
6118       <listitem>
6119        <para>
6120         The century:
6121        </para>
6122
6123 <screen>
6124 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6125 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6126 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6127 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6128 </screen>
6129
6130        <para>
6131         The first century starts at 0001-01-01 00:00:00 AD, although
6132         they did not know it at the time. This definition applies to all
6133         Gregorian calendar countries. There is no century number 0,
6134         you go from -1 century to 1 century.
6135
6136         If you disagree with this, please write your complaint to:
6137         Pope, Cathedral Saint-Peter of Roma, Vatican.
6138        </para>
6139
6140        <para>
6141         <productname>PostgreSQL</productname> releases before 8.0 did not
6142         follow the conventional numbering of centuries, but just returned
6143         the year field divided by 100.
6144        </para>
6145       </listitem>
6146      </varlistentry>
6147
6148      <varlistentry>
6149       <term><literal>day</literal></term>
6150       <listitem>
6151        <para>
6152         The day (of the month) field (1 - 31)
6153        </para>
6154
6155 <screen>
6156 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6157 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6158 </screen>
6159       </listitem>
6160      </varlistentry>
6161
6162      <varlistentry>
6163       <term><literal>decade</literal></term>
6164       <listitem>
6165        <para>
6166         The year field divided by 10
6167        </para>
6168
6169 <screen>
6170 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6171 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6172 </screen>
6173       </listitem>
6174      </varlistentry>
6175
6176      <varlistentry>
6177       <term><literal>dow</literal></term>
6178       <listitem>
6179        <para>
6180         The day of the week as Sunday(<literal>0</>) to
6181         Saturday(<literal>6</>)
6182        </para>
6183
6184 <screen>
6185 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6186 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6187 </screen>
6188        <para>
6189         Note that <function>extract</function>'s day of the week numbering
6190         differs from that of the <function>to_char(...,
6191         'D')</function> function.
6192        </para>
6193
6194       </listitem>
6195      </varlistentry>
6196
6197      <varlistentry>
6198       <term><literal>doy</literal></term>
6199       <listitem>
6200        <para>
6201         The day of the year (1 - 365/366)
6202        </para>
6203
6204 <screen>
6205 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6206 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6207 </screen>
6208       </listitem>
6209      </varlistentry>
6210
6211      <varlistentry>
6212       <term><literal>epoch</literal></term>
6213       <listitem>
6214        <para>
6215         For <type>date</type> and <type>timestamp</type> values, the
6216         number of seconds since 1970-01-01 00:00:00-00 GMT (can be negative);
6217         for <type>interval</type> values, the total number
6218         of seconds in the interval
6219        </para>
6220
6221 <screen>
6222 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-08');
6223 <lineannotation>Result: </lineannotation><computeroutput>982384720</computeroutput>
6224
6225 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6226 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6227 </screen>
6228
6229        <para>
6230         Here is how you can convert an epoch value back to a time
6231         stamp:
6232        </para>
6233
6234 <screen>
6235 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720 * INTERVAL '1 second';
6236 </screen>
6237       </listitem>
6238      </varlistentry>
6239
6240      <varlistentry>
6241       <term><literal>hour</literal></term>
6242       <listitem>
6243        <para>
6244         The hour field (0 - 23)
6245        </para>
6246
6247 <screen>
6248 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6249 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6250 </screen>
6251       </listitem>
6252      </varlistentry>
6253
6254      <varlistentry>
6255       <term><literal>isodow</literal></term>
6256       <listitem>
6257        <para>
6258         The day of the week as Monday(<literal>1</>) to
6259         Sunday(<literal>7</>)
6260        </para>
6261
6262 <screen>
6263 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6264 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6265 </screen>
6266        <para>
6267         This is identical to <literal>dow</> except for Sunday.  This
6268         matches the <acronym>ISO</> 8601 day of the week numbering.
6269        </para>
6270
6271       </listitem>
6272      </varlistentry>
6273
6274      <varlistentry>
6275       <term><literal>isoyear</literal></term>
6276       <listitem>
6277        <para>
6278         The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals)
6279        </para>
6280
6281 <screen>
6282 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6283 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6284 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6285 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6286 </screen>
6287
6288        <para>
6289         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.
6290        </para>
6291        <para>
6292         This field is not available in PostgreSQL releases prior to 8.3.
6293        </para>
6294       </listitem>
6295      </varlistentry>
6296
6297      <varlistentry>
6298       <term><literal>microseconds</literal></term>
6299       <listitem>
6300        <para>
6301         The seconds field, including fractional parts, multiplied by 1
6302         000 000;  note that this includes full seconds
6303        </para>
6304
6305 <screen>
6306 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6307 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6308 </screen>
6309       </listitem>
6310      </varlistentry>
6311
6312      <varlistentry>
6313       <term><literal>millennium</literal></term>
6314       <listitem>
6315        <para>
6316         The millennium
6317        </para>
6318
6319 <screen>
6320 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6321 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6322 </screen>
6323
6324        <para>
6325         Years in the 1900s are in the second millennium.
6326         The third millennium started January 1, 2001.
6327        </para>
6328
6329        <para>
6330         <productname>PostgreSQL</productname> releases before 8.0 did not
6331         follow the conventional numbering of millennia, but just returned
6332         the year field divided by 1000.
6333        </para>
6334       </listitem>
6335      </varlistentry>
6336
6337      <varlistentry>
6338       <term><literal>milliseconds</literal></term>
6339       <listitem>
6340        <para>
6341         The seconds field, including fractional parts, multiplied by
6342         1000.  Note that this includes full seconds.
6343        </para>
6344
6345 <screen>
6346 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6347 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6348 </screen>
6349       </listitem>
6350      </varlistentry>
6351
6352      <varlistentry>
6353       <term><literal>minute</literal></term>
6354       <listitem>
6355        <para>
6356         The minutes field (0 - 59)
6357        </para>
6358
6359 <screen>
6360 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6361 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6362 </screen>
6363       </listitem>
6364      </varlistentry>
6365
6366      <varlistentry>
6367       <term><literal>month</literal></term>
6368       <listitem>
6369        <para>
6370         For <type>timestamp</type> values, the number of the month
6371         within the year (1 - 12) ; for <type>interval</type> values
6372         the number of months, modulo 12 (0 - 11)
6373        </para>
6374
6375 <screen>
6376 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6377 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6378
6379 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6380 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6381
6382 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6383 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6384 </screen>
6385       </listitem>
6386      </varlistentry>
6387
6388      <varlistentry>
6389       <term><literal>quarter</literal></term>
6390       <listitem>
6391        <para>
6392         The quarter of the year (1 - 4) that the date is in
6393        </para>
6394
6395 <screen>
6396 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6397 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6398 </screen>
6399       </listitem>
6400      </varlistentry>
6401
6402      <varlistentry>
6403       <term><literal>second</literal></term>
6404       <listitem>
6405        <para>
6406         The seconds field, including fractional parts (0 -
6407         59<footnote><simpara>60 if leap seconds are
6408         implemented by the operating system</simpara></footnote>)
6409        </para>
6410
6411 <screen>
6412 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6413 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6414
6415 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6416 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6417 </screen>
6418       </listitem>
6419      </varlistentry>
6420      <varlistentry>
6421       <term><literal>timezone</literal></term>
6422       <listitem>
6423        <para>
6424         The time zone offset from UTC, measured in seconds.  Positive values
6425         correspond to time zones east of UTC, negative values to
6426         zones west of UTC.
6427        </para>
6428       </listitem>
6429      </varlistentry>
6430
6431      <varlistentry>
6432       <term><literal>timezone_hour</literal></term>
6433       <listitem>
6434        <para>
6435         The hour component of the time zone offset
6436        </para>
6437       </listitem>
6438      </varlistentry>
6439
6440      <varlistentry>
6441       <term><literal>timezone_minute</literal></term>
6442       <listitem>
6443        <para>
6444         The minute component of the time zone offset
6445        </para>
6446       </listitem>
6447      </varlistentry>
6448
6449      <varlistentry>
6450       <term><literal>week</literal></term>
6451       <listitem>
6452        <para>
6453         The number of the week of the year that the day is in.  By definition
6454         (<acronym>ISO</acronym> 8601), the first week of a year
6455         contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
6456         week starts on Monday.)  In other words, the first Thursday of
6457         a year is in week 1 of that year.
6458        </para>
6459        <para>
6460         Because of this, it is possible for early January dates to be part of the 
6461         52nd or 53rd week of the previous year.  For example, <literal>2005-01-01</>
6462         is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of 
6463         the 52nd week of year 2005.
6464        </para>
6465
6466 <screen>
6467 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6468 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6469 </screen>
6470       </listitem>
6471      </varlistentry>
6472
6473      <varlistentry>
6474       <term><literal>year</literal></term>
6475       <listitem>
6476        <para>
6477         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting 
6478         <literal>BC</> years from <literal>AD</> years should be done with care.
6479        </para>
6480
6481 <screen>
6482 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6483 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6484 </screen>
6485       </listitem>
6486      </varlistentry>
6487
6488     </variablelist>
6489    </para>
6490
6491    <para>
6492     The <function>extract</function> function is primarily intended
6493     for computational processing.  For formatting date/time values for
6494     display, see <xref linkend="functions-formatting">.
6495    </para>
6496
6497    <para>
6498     The <function>date_part</function> function is modeled on the traditional
6499     <productname>Ingres</productname> equivalent to the
6500     <acronym>SQL</acronym>-standard function <function>extract</function>:
6501 <synopsis>
6502 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6503 </synopsis>
6504     Note that here the <replaceable>field</replaceable> parameter needs to
6505     be a string value, not a name.  The valid field names for
6506     <function>date_part</function> are the same as for
6507     <function>extract</function>.
6508    </para>
6509
6510 <screen>
6511 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
6512 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6513
6514 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
6515 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
6516 </screen>
6517
6518   </sect2>
6519
6520   <sect2 id="functions-datetime-trunc">
6521    <title><function>date_trunc</function></title>
6522
6523    <indexterm>
6524     <primary>date_trunc</primary>
6525    </indexterm>
6526
6527    <para>
6528     The function <function>date_trunc</function> is conceptually
6529     similar to the <function>trunc</function> function for numbers.
6530    </para>
6531
6532    <para>
6533 <synopsis>
6534 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6535 </synopsis>
6536     <replaceable>source</replaceable> is a value expression of type
6537     <type>timestamp</type> or <type>interval</>.
6538     (Values of type <type>date</type> and
6539     <type>time</type> are cast automatically to <type>timestamp</type> or
6540     <type>interval</>, respectively.)
6541     <replaceable>field</replaceable> selects to which precision to
6542     truncate the input value.  The return value is of type
6543     <type>timestamp</type> or <type>interval</>
6544     with all fields that are less significant than the
6545     selected one set to zero (or one, for day and month).
6546    </para>
6547
6548    <para>
6549     Valid values for <replaceable>field</replaceable> are:
6550     <simplelist>
6551      <member><literal>microseconds</literal></member>
6552      <member><literal>milliseconds</literal></member>
6553      <member><literal>second</literal></member>
6554      <member><literal>minute</literal></member>
6555      <member><literal>hour</literal></member>
6556      <member><literal>day</literal></member>
6557      <member><literal>week</literal></member>
6558      <member><literal>month</literal></member>
6559      <member><literal>quarter</literal></member>
6560      <member><literal>year</literal></member>
6561      <member><literal>decade</literal></member>
6562      <member><literal>century</literal></member>
6563      <member><literal>millennium</literal></member>
6564     </simplelist>
6565    </para>
6566
6567    <para>
6568     Examples:
6569 <screen>
6570 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
6571 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
6572
6573 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
6574 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
6575 </screen>
6576    </para>
6577   </sect2>
6578
6579   <sect2 id="functions-datetime-zoneconvert">
6580    <title><literal>AT TIME ZONE</literal></title>
6581
6582    <indexterm>
6583     <primary>time zone</primary>
6584     <secondary>conversion</secondary>
6585    </indexterm>
6586
6587    <indexterm>
6588     <primary>AT TIME ZONE</primary>
6589    </indexterm>
6590
6591    <para>
6592     The <literal>AT TIME ZONE</literal> construct allows conversions
6593     of time stamps to different time zones.  <xref
6594     linkend="functions-datetime-zoneconvert-table"> shows its
6595     variants.
6596    </para>
6597
6598     <table id="functions-datetime-zoneconvert-table">
6599      <title><literal>AT TIME ZONE</literal> Variants</title>
6600      <tgroup cols="3">
6601       <thead>
6602        <row>
6603         <entry>Expression</entry>
6604         <entry>Return Type</entry>
6605         <entry>Description</entry>
6606        </row>
6607       </thead>
6608
6609       <tbody>
6610        <row>
6611         <entry>
6612          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6613         </entry>
6614         <entry><type>timestamp with time zone</type></entry>
6615         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
6616        </row>
6617
6618        <row>
6619         <entry>
6620          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6621         </entry>
6622         <entry><type>timestamp without time zone</type></entry>
6623         <entry>Convert given time stamp <emphasis>with time zone</> to the new time
6624         zone, with no time zone designation</entry>
6625        </row>
6626
6627        <row>
6628         <entry>
6629          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6630         </entry>
6631         <entry><type>time with time zone</type></entry>
6632         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
6633        </row>
6634       </tbody>
6635      </tgroup>
6636     </table>
6637
6638    <para>
6639     In these expressions, the desired time zone <replaceable>zone</> can be
6640     specified either as a text string (e.g., <literal>'PST'</literal>)
6641     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
6642     In the text case, a time zone name can be specified in any of the ways
6643     described in <xref linkend="datatype-timezones">.
6644    </para>
6645
6646    <para>
6647     Examples (assuming the local time zone is <literal>PST8PDT</>):
6648 <screen>
6649 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
6650 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
6651
6652 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
6653 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
6654 </screen>
6655     The first example takes a time stamp without time zone and interprets it as MST time
6656     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes 
6657     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
6658    </para>
6659
6660    <para>
6661     The function <literal><function>timezone</function>(<replaceable>zone</>,
6662     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
6663     <literal><replaceable>timestamp</> AT TIME ZONE
6664     <replaceable>zone</></literal>. 
6665    </para>
6666   </sect2>
6667
6668   <sect2 id="functions-datetime-current">
6669    <title>Current Date/Time</title>
6670
6671    <indexterm>
6672     <primary>date</primary>
6673     <secondary>current</secondary>
6674    </indexterm>
6675
6676    <indexterm>
6677     <primary>time</primary>
6678     <secondary>current</secondary>
6679    </indexterm>
6680
6681    <para>
6682     <productname>PostgreSQL</productname> provides a number of functions
6683     that return values related to the current date and time.  These
6684     SQL-standard functions all return values based on the start time of
6685     the current transaction:
6686 <synopsis>
6687 CURRENT_DATE
6688 CURRENT_TIME
6689 CURRENT_TIMESTAMP
6690 CURRENT_TIME(<replaceable>precision</replaceable>)
6691 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
6692 LOCALTIME
6693 LOCALTIMESTAMP
6694 LOCALTIME(<replaceable>precision</replaceable>)
6695 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
6696 </synopsis>
6697     </para>
6698
6699     <para>
6700      <function>CURRENT_TIME</function> and
6701      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
6702      <function>LOCALTIME</function> and
6703      <function>LOCALTIMESTAMP</function> deliver values without time zone.
6704     </para>
6705
6706     <para>
6707      <function>CURRENT_TIME</function>,
6708      <function>CURRENT_TIMESTAMP</function>,
6709      <function>LOCALTIME</function>, and
6710      <function>LOCALTIMESTAMP</function>
6711      can optionally take
6712      a precision parameter, which causes the result to be rounded
6713      to that many fractional digits in the seconds field.  Without a precision parameter,
6714      the result is given to the full available precision.
6715     </para>
6716
6717    <para>
6718     Some examples:
6719 <screen>
6720 SELECT CURRENT_TIME;
6721 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
6722
6723 SELECT CURRENT_DATE;
6724 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
6725
6726 SELECT CURRENT_TIMESTAMP;
6727 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
6728
6729 SELECT CURRENT_TIMESTAMP(2);
6730 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
6731
6732 SELECT LOCALTIMESTAMP;
6733 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
6734 </screen>
6735    </para>
6736
6737    <para>
6738     Since these functions return
6739     the start time of the current transaction, their values do not
6740     change during the transaction. This is considered a feature:
6741     the intent is to allow a single transaction to have a consistent
6742     notion of the <quote>current</quote> time, so that multiple
6743     modifications within the same transaction bear the same
6744     time stamp.
6745    </para>
6746
6747    <note>
6748     <para>
6749      Other database systems might advance these values more
6750      frequently.
6751     </para>
6752    </note>
6753
6754    <para>
6755     <productname>PostgreSQL</productname> also provides functions that
6756     return the start time of the current statement, as well as the actual
6757     current time at the instant the function is called.  The complete list
6758     of non-SQL-standard time functions is:
6759 <synopsis>
6760 transaction_timestamp()
6761 statement_timestamp()
6762 clock_timestamp()
6763 timeofday()
6764 now()
6765 </synopsis>
6766    </para>
6767
6768    <para>
6769     <function>statement_timestamp()</> returns the start time of the current
6770     statement (more specifically, the time of receipt of the latest command
6771     message from the client).
6772     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
6773     return the same value during the first command of a transaction, but might
6774     differ during subsequent commands.
6775     <function>clock_timestamp()</> returns the actual current time, and
6776     therefore its value changes even within a single SQL command.
6777     <function>timeofday()</> is a historical
6778     <productname>PostgreSQL</productname> function.  Like
6779     <function>clock_timestamp()</>, it returns the actual current time,
6780     but as a formatted <type>text</> string rather than a <type>timestamp
6781     with time zone</> value.
6782     <function>now()</> is a traditional <productname>PostgreSQL</productname>
6783     equivalent to <function>CURRENT_TIMESTAMP</function>.
6784     <function>transaction_timestamp()</> is likewise equivalent to
6785     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
6786     what it returns.
6787    </para>
6788
6789    <para>
6790     All the date/time data types also accept the special literal value
6791     <literal>now</literal> to specify the current date and time (again,
6792     interpreted as the transaction start time).  Thus,
6793     the following three all return the same result:
6794 <programlisting>
6795 SELECT CURRENT_TIMESTAMP;
6796 SELECT now();
6797 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
6798 </programlisting>
6799    </para>
6800
6801     <tip>
6802      <para>
6803       You do not want to use the third form when specifying a <literal>DEFAULT</>
6804       clause while creating a table.  The system will convert <literal>now</literal>
6805       to a <type>timestamp</type> as soon as the constant is parsed, so that when
6806       the default value is needed,
6807       the time of the table creation would be used!  The first two
6808       forms will not be evaluated until the default value is used,
6809       because they are function calls.  Thus they will give the desired
6810       behavior of defaulting to the time of row insertion.
6811      </para>
6812     </tip>
6813   </sect2>
6814
6815   <sect2 id="functions-datetime-delay">
6816    <title>Delaying Execution</title>
6817
6818    <indexterm>
6819     <primary>pg_sleep</primary>
6820    </indexterm>
6821    <indexterm>
6822     <primary>sleep</primary>
6823    </indexterm>
6824    <indexterm>
6825     <primary>delay</primary>
6826    </indexterm>
6827
6828    <para>
6829     The following function is available to delay execution of the server
6830     process:
6831 <synopsis>
6832 pg_sleep(<replaceable>seconds</replaceable>)
6833 </synopsis>
6834
6835     <function>pg_sleep</function> makes the current session's process
6836     sleep until <replaceable>seconds</replaceable> seconds have
6837     elapsed.  <replaceable>seconds</replaceable> is a value of type
6838     <type>double precision</>, so fractional-second delays can be specified.
6839     For example:
6840
6841 <programlisting>
6842 SELECT pg_sleep(1.5);
6843 </programlisting>
6844    </para>
6845
6846    <note>
6847      <para>
6848       The effective resolution of the sleep interval is platform-specific;
6849       0.01 seconds is a common value.  The sleep delay will be at least as long
6850       as specified. It might be longer depending on factors such as server load.
6851      </para>
6852    </note>
6853
6854    <warning>
6855      <para>
6856       Make sure that your session does not hold more locks than necessary
6857       when calling <function>pg_sleep</function>.  Otherwise other sessions
6858       might have to wait for your sleeping process, slowing down the entire
6859       system.
6860      </para>
6861    </warning>
6862   </sect2>
6863
6864  </sect1>
6865
6866   
6867  <sect1 id="functions-enum">
6868   <title>Enum Support Functions</title>
6869
6870   <para>
6871    For enum types (described in <xref linkend="datatype-enum">),
6872    there are several functions that allow cleaner programming without
6873    hard-coding particular values of an enum type.
6874    These are listed in <xref linkend="functions-enum-table">. The examples
6875    assume an enum type created as:
6876
6877 <programlisting>
6878 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
6879 </programlisting>
6880
6881   </para>
6882
6883   <table id="functions-enum-table">
6884     <title>Enum Support Functions</title>
6885     <tgroup cols="4">
6886      <thead>
6887       <row>
6888        <entry>Function</entry>
6889        <entry>Description</entry>
6890        <entry>Example</entry>
6891        <entry>Example Result</entry>
6892       </row>
6893      </thead>
6894      <tbody>
6895       <row>
6896        <entry><literal>enum_first(anyenum)</literal></entry>
6897        <entry>Returns the first value of the input enum type</entry>
6898        <entry><literal>enum_first(null::rainbow)</literal></entry>
6899        <entry><literal>red</literal></entry>
6900       </row>
6901       <row>
6902        <entry><literal>enum_last(anyenum)</literal></entry>
6903        <entry>Returns the last value of the input enum type</entry>
6904        <entry><literal>enum_last(null::rainbow)</literal></entry>
6905        <entry><literal>purple</literal></entry>
6906       </row>
6907       <row>
6908        <entry><literal>enum_range(anyenum)</literal></entry>
6909        <entry>Returns all values of the input enum type in an ordered array</entry>
6910        <entry><literal>enum_range(null::rainbow)</literal></entry>
6911        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
6912       </row>
6913       <row>
6914        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
6915        <entry morerows="2">
6916         Returns the range between the two given enum values, as an ordered
6917         array. The values must be from the same enum type. If the first
6918         parameter is null, the result will start with the first value of
6919         the enum type.
6920         If the second parameter is null, the result will end with the last
6921         value of the enum type.
6922        </entry>
6923        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
6924        <entry><literal>{orange,yellow,green}</literal></entry>
6925       </row>
6926       <row>
6927        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
6928        <entry><literal>{red,orange,yellow,green}</literal></entry>
6929       </row>
6930       <row>
6931        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
6932        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
6933       </row>
6934      </tbody>
6935     </tgroup>
6936    </table>
6937
6938    <para>
6939     Notice that except for the two-argument form of <function>enum_range</>,
6940     these functions disregard the specific value passed to them; they care
6941     only about its declared data type.  Either null or a specific value of
6942     the type can be passed, with the same result.  It is more common to
6943     apply these functions to a table column or function argument than to
6944     a hardwired type name as suggested by the examples.
6945    </para>
6946  </sect1>
6947
6948  <sect1 id="functions-geometry">
6949   <title>Geometric Functions and Operators</title>
6950
6951    <para>
6952     The geometric types <type>point</type>, <type>box</type>,
6953     <type>lseg</type>, <type>line</type>, <type>path</type>,
6954     <type>polygon</type>, and <type>circle</type> have a large set of
6955     native support functions and operators, shown in <xref
6956     linkend="functions-geometry-op-table">, <xref
6957     linkend="functions-geometry-func-table">, and <xref
6958     linkend="functions-geometry-conv-table">.
6959    </para>
6960
6961    <caution>
6962     <para>
6963      Note that the <quote>same as</> operator, <literal>~=</>, represents
6964      the usual notion of equality for the <type>point</type>,
6965      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
6966      Some of these types also have an <literal>=</> operator, but
6967      <literal>=</> compares
6968      for equal <emphasis>areas</> only.  The other scalar comparison operators
6969      (<literal>&lt;=</> and so on) likewise compare areas for these types.
6970     </para>
6971    </caution>
6972
6973    <table id="functions-geometry-op-table">
6974      <title>Geometric Operators</title>
6975      <tgroup cols="3">
6976       <thead>
6977        <row>
6978         <entry>Operator</entry>
6979         <entry>Description</entry>
6980         <entry>Example</entry>
6981        </row>
6982       </thead>
6983       <tbody>
6984        <row>
6985         <entry> <literal>+</literal> </entry>
6986         <entry>Translation</entry>
6987         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
6988        </row>
6989        <row>
6990         <entry> <literal>-</literal> </entry>
6991         <entry>Translation</entry>
6992         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
6993        </row>
6994        <row>
6995         <entry> <literal>*</literal> </entry>
6996         <entry>Scaling/rotation</entry>
6997         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
6998        </row>
6999        <row>
7000         <entry> <literal>/</literal> </entry>
7001         <entry>Scaling/rotation</entry>
7002         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
7003        </row>
7004        <row>
7005         <entry> <literal>#</literal> </entry>
7006         <entry>Point or box of intersection</entry>
7007         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
7008        </row>
7009        <row>
7010         <entry> <literal>#</literal> </entry>
7011         <entry>Number of points in path or polygon</entry>
7012         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
7013        </row>
7014        <row>
7015         <entry> <literal>@-@</literal> </entry>
7016         <entry>Length or circumference</entry>
7017         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
7018        </row>
7019        <row>
7020         <entry> <literal>@@</literal> </entry>
7021         <entry>Center</entry>
7022         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
7023        </row>
7024        <row>
7025         <entry> <literal>##</literal> </entry>
7026         <entry>Closest point to first operand on second operand</entry>
7027         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
7028        </row>
7029        <row>
7030         <entry> <literal>&lt;-&gt;</literal> </entry>
7031         <entry>Distance between</entry>
7032         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
7033        </row>
7034        <row>
7035         <entry> <literal>&amp;&amp;</literal> </entry>
7036         <entry>Overlaps?</entry>
7037         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
7038        </row>
7039        <row>
7040         <entry> <literal>&lt;&lt;</literal> </entry>
7041         <entry>Is strictly left of?</entry>
7042         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
7043        </row>
7044        <row>
7045         <entry> <literal>&gt;&gt;</literal> </entry>
7046         <entry>Is strictly right of?</entry>
7047         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
7048        </row>
7049        <row>
7050         <entry> <literal>&amp;&lt;</literal> </entry>
7051         <entry>Does not extend to the right of?</entry>
7052         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
7053        </row>
7054        <row>
7055         <entry> <literal>&amp;&gt;</literal> </entry>
7056         <entry>Does not extend to the left of?</entry>
7057         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
7058        </row>
7059        <row>
7060         <entry> <literal>&lt;&lt;|</literal> </entry>
7061         <entry>Is strictly below?</entry>
7062         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
7063        </row>
7064        <row>
7065         <entry> <literal>|&gt;&gt;</literal> </entry>
7066         <entry>Is strictly above?</entry>
7067         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
7068        </row>
7069        <row>
7070         <entry> <literal>&amp;&lt;|</literal> </entry>
7071         <entry>Does not extend above?</entry>
7072         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
7073        </row>
7074        <row>
7075         <entry> <literal>|&amp;&gt;</literal> </entry>
7076         <entry>Does not extend below?</entry>
7077         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
7078        </row>
7079        <row>
7080         <entry> <literal>&lt;^</literal> </entry>
7081         <entry>Is below (allows touching)?</entry>
7082         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
7083        </row>
7084        <row>
7085         <entry> <literal>&gt;^</literal> </entry>
7086         <entry>Is above (allows touching)?</entry>
7087         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
7088        </row>
7089        <row>
7090         <entry> <literal>?#</literal> </entry>
7091         <entry>Intersects?</entry>
7092         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7093        </row>
7094        <row>
7095         <entry> <literal>?-</literal> </entry>
7096         <entry>Is horizontal?</entry>
7097         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7098        </row>
7099        <row>
7100         <entry> <literal>?-</literal> </entry>
7101         <entry>Are horizontally aligned?</entry>
7102         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7103        </row>
7104        <row>
7105         <entry> <literal>?|</literal> </entry>
7106         <entry>Is vertical?</entry>
7107         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7108        </row>
7109        <row>
7110         <entry> <literal>?|</literal> </entry>
7111         <entry>Are vertically aligned?</entry>
7112         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7113        </row>
7114        <row>
7115         <entry> <literal>?-|</literal> </entry>
7116         <entry>Is perpendicular?</entry>
7117         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7118        </row>
7119        <row>
7120         <entry> <literal>?||</literal> </entry>
7121         <entry>Are parallel?</entry>
7122         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7123        </row>
7124        <row>
7125         <entry> <literal>@&gt;</literal> </entry>
7126         <entry>Contains?</entry>
7127         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7128        </row>
7129        <row>
7130         <entry> <literal>&lt;@</literal> </entry>
7131         <entry>Contained in or on?</entry>
7132         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7133        </row>
7134        <row>
7135         <entry> <literal>~=</literal> </entry>
7136         <entry>Same as?</entry>
7137         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7138        </row>
7139       </tbody>
7140      </tgroup>
7141    </table>
7142
7143    <note>
7144     <para>
7145      Before <productname>PostgreSQL</productname> 8.2, the containment
7146      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7147      called <literal>~</> and <literal>@</>.  These names are still
7148      available, but are deprecated and will eventually be removed.
7149     </para>
7150    </note>
7151
7152    <indexterm>
7153     <primary>area</primary>
7154    </indexterm>
7155    <indexterm>
7156     <primary>center</primary>
7157    </indexterm>
7158    <indexterm>
7159     <primary>diameter</primary>
7160    </indexterm>
7161    <indexterm>
7162     <primary>height</primary>
7163    </indexterm>
7164    <indexterm>
7165     <primary>isclosed</primary>
7166    </indexterm>
7167    <indexterm>
7168     <primary>isopen</primary>
7169    </indexterm>
7170    <indexterm>
7171     <primary>length</primary>
7172    </indexterm>
7173    <indexterm>
7174     <primary>npoints</primary>
7175    </indexterm>
7176    <indexterm>
7177     <primary>pclose</primary>
7178    </indexterm>
7179    <indexterm>
7180     <primary>popen</primary>
7181    </indexterm>
7182    <indexterm>
7183     <primary>radius</primary>
7184    </indexterm>
7185    <indexterm>
7186     <primary>width</primary>
7187    </indexterm>
7188
7189    <table id="functions-geometry-func-table">
7190      <title>Geometric Functions</title>
7191      <tgroup cols="4">
7192       <thead>
7193        <row>
7194         <entry>Function</entry>
7195         <entry>Return Type</entry>
7196         <entry>Description</entry>
7197         <entry>Example</entry>
7198        </row>
7199       </thead>
7200       <tbody>
7201        <row>
7202         <entry><literal><function>area</function>(<replaceable>object</>)</literal></entry>
7203         <entry><type>double precision</type></entry>
7204         <entry>area</entry>
7205         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7206        </row>
7207        <row>
7208         <entry><literal><function>center</function>(<replaceable>object</>)</literal></entry>
7209         <entry><type>point</type></entry>
7210         <entry>center</entry>
7211         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7212        </row>
7213        <row>
7214         <entry><literal><function>diameter</function>(<type>circle</>)</literal></entry>
7215         <entry><type>double precision</type></entry>
7216         <entry>diameter of circle</entry>
7217         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7218        </row>
7219        <row>
7220         <entry><literal><function>height</function>(<type>box</>)</literal></entry>
7221         <entry><type>double precision</type></entry>
7222         <entry>vertical size of box</entry>
7223         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7224        </row>
7225        <row>
7226         <entry><literal><function>isclosed</function>(<type>path</>)</literal></entry>
7227         <entry><type>boolean</type></entry>
7228         <entry>a closed path?</entry>
7229         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7230        </row>
7231        <row>
7232         <entry><literal><function>isopen</function>(<type>path</>)</literal></entry>
7233         <entry><type>boolean</type></entry>
7234         <entry>an open path?</entry>
7235         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7236        </row>
7237        <row>
7238         <entry><literal><function>length</function>(<replaceable>object</>)</literal></entry>
7239         <entry><type>double precision</type></entry>
7240         <entry>length</entry>
7241         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7242        </row>
7243        <row>
7244         <entry><literal><function>npoints</function>(<type>path</>)</literal></entry>
7245         <entry><type>int</type></entry>
7246         <entry>number of points</entry>
7247         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7248        </row>
7249        <row>
7250         <entry><literal><function>npoints</function>(<type>polygon</>)</literal></entry>
7251         <entry><type>int</type></entry>
7252         <entry>number of points</entry>
7253         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7254        </row>
7255        <row>
7256         <entry><literal><function>pclose</function>(<type>path</>)</literal></entry>
7257         <entry><type>path</type></entry>
7258         <entry>convert path to closed</entry>
7259         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7260        </row>
7261 <![IGNORE[
7262 <!-- Not defined by this name. Implements the intersection operator '#' -->
7263        <row>
7264         <entry><literal><function>point</function>(<type>lseg</>, <type>lseg</>)</literal></entry>
7265         <entry><type>point</type></entry>
7266         <entry>intersection</entry>
7267         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7268        </row>
7269 ]]>
7270        <row>
7271         <entry><literal><function>popen</function>(<type>path</>)</literal></entry>
7272         <entry><type>path</type></entry>
7273         <entry>convert path to open</entry>
7274         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7275        </row>
7276        <row>
7277         <entry><literal><function>radius</function>(<type>circle</type>)</literal></entry>
7278         <entry><type>double precision</type></entry>
7279         <entry>radius of circle</entry>
7280         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7281        </row>
7282        <row>
7283         <entry><literal><function>width</function>(<type>box</>)</literal></entry>
7284         <entry><type>double precision</type></entry>
7285         <entry>horizontal size of box</entry>
7286         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7287        </row>
7288       </tbody>
7289      </tgroup>
7290    </table>
7291
7292    <table id="functions-geometry-conv-table">
7293      <title>Geometric Type Conversion Functions</title>
7294      <tgroup cols="4">
7295       <thead>
7296        <row>
7297         <entry>Function</entry>
7298         <entry>Return Type</entry>
7299         <entry>Description</entry>
7300         <entry>Example</entry>
7301        </row>
7302       </thead>
7303       <tbody>
7304        <row>
7305         <entry><literal><function>box</function>(<type>circle</type>)</literal></entry>
7306         <entry><type>box</type></entry>
7307         <entry>circle to box</entry>
7308         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7309        </row>
7310        <row>
7311         <entry><literal><function>box</function>(<type>point</type>, <type>point</type>)</literal></entry>
7312         <entry><type>box</type></entry>
7313         <entry>points to box</entry>
7314         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7315        </row>
7316        <row>
7317         <entry><literal><function>box</function>(<type>polygon</type>)</literal></entry>
7318         <entry><type>box</type></entry>
7319         <entry>polygon to box</entry>
7320         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7321        </row>
7322        <row>
7323         <entry><literal><function>circle</function>(<type>box</type>)</literal></entry>
7324         <entry><type>circle</type></entry>
7325         <entry>box to circle</entry>
7326         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7327        </row>
7328        <row>
7329         <entry><literal><function>circle</function>(<type>point</type>, <type>double precision</type>)</literal></entry>
7330         <entry><type>circle</type></entry>
7331         <entry>center and radius to circle</entry>
7332         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7333        </row>
7334        <row>
7335         <entry><literal><function>circle</function>(<type>polygon</type>)</literal></entry>
7336         <entry><type>circle</type></entry>
7337         <entry>polygon to circle</entry>
7338         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7339        </row>
7340        <row>
7341         <entry><literal><function>lseg</function>(<type>box</type>)</literal></entry>
7342         <entry><type>lseg</type></entry>
7343         <entry>box diagonal to line segment</entry>
7344         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7345        </row>
7346        <row>
7347         <entry><literal><function>lseg</function>(<type>point</type>, <type>point</type>)</literal></entry>
7348         <entry><type>lseg</type></entry>
7349         <entry>points to line segment</entry>
7350         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7351        </row>
7352        <row>
7353         <entry><literal><function>path</function>(<type>polygon</type>)</literal></entry>
7354         <entry><type>point</type></entry>
7355         <entry>polygon to path</entry>
7356         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7357        </row>
7358        <row>
7359         <entry><literal><function>point</function>(<type>double
7360          precision</type>, <type>double precision</type>)</literal></entry>
7361         <entry><type>point</type></entry>
7362         <entry>construct point</entry>
7363         <entry><literal>point(23.4, -44.5)</literal></entry>
7364        </row>
7365        <row>
7366         <entry><literal><function>point</function>(<type>box</type>)</literal></entry>
7367         <entry><type>point</type></entry>
7368         <entry>center of box</entry>
7369         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7370        </row>
7371        <row>
7372         <entry><literal><function>point</function>(<type>circle</type>)</literal></entry>
7373         <entry><type>point</type></entry>
7374         <entry>center of circle</entry>
7375         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7376        </row>
7377        <row>
7378         <entry><literal><function>point</function>(<type>lseg</type>)</literal></entry>
7379         <entry><type>point</type></entry>
7380         <entry>center of line segment</entry>
7381         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7382        </row>
7383        <row>
7384         <entry><literal><function>point</function>(<type>polygon</type>)</literal></entry>
7385         <entry><type>point</type></entry>
7386         <entry>center of polygon</entry>
7387         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7388        </row>
7389        <row>
7390         <entry><literal><function>polygon</function>(<type>box</type>)</literal></entry>
7391         <entry><type>polygon</type></entry>
7392         <entry>box to 4-point polygon</entry>
7393         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7394        </row>
7395        <row>
7396         <entry><literal><function>polygon</function>(<type>circle</type>)</literal></entry>
7397         <entry><type>polygon</type></entry>
7398         <entry>circle to 12-point polygon</entry>
7399         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7400        </row>
7401        <row>
7402         <entry><literal><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</literal></entry>
7403         <entry><type>polygon</type></entry>
7404         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
7405         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7406        </row>
7407        <row>
7408         <entry><literal><function>polygon</function>(<type>path</type>)</literal></entry>
7409         <entry><type>polygon</type></entry>
7410         <entry>path to polygon</entry>
7411         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7412        </row>
7413       </tbody>
7414      </tgroup>
7415    </table>
7416
7417     <para>
7418      It is possible to access the two component numbers of a <type>point</>
7419      as though they were an array with indices 0 and 1.  For example, if
7420      <literal>t.p</> is a <type>point</> column then
7421      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7422      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7423      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7424      as an array of two <type>point</> values.
7425     </para>
7426
7427     <para>
7428      The <function>area</function> function works for the types
7429      <type>box</type>, <type>circle</type>, and <type>path</type>.
7430      The <function>area</function> function only works on the
7431      <type>path</type> data type if the points in the
7432      <type>path</type> are non-intersecting.  For example, the
7433      <type>path</type>
7434      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7435      will not work;  however, the following visually identical
7436      <type>path</type>
7437      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7438      will work.  If the concept of an intersecting versus
7439      non-intersecting <type>path</type> is confusing, draw both of the
7440      above <type>path</type>s side by side on a piece of graph paper.
7441     </para>
7442
7443   </sect1>
7444
7445
7446  <sect1 id="functions-net">
7447   <title>Network Address Functions and Operators</title>
7448
7449   <para>
7450    <xref linkend="cidr-inet-operators-table"> shows the operators
7451    available for the <type>cidr</type> and <type>inet</type> types.
7452    The operators <literal>&lt;&lt;</literal>,
7453    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
7454    <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
7455    consider only the network parts of the two addresses (ignoring any
7456    host part) and determine whether one network is identical to
7457    or a subnet of the other.
7458   </para>
7459
7460     <table id="cidr-inet-operators-table">
7461      <title><type>cidr</type> and <type>inet</type> Operators</title>
7462      <tgroup cols="3">
7463       <thead>
7464        <row>
7465         <entry>Operator</entry>
7466         <entry>Description</entry>
7467         <entry>Example</entry>
7468        </row>
7469       </thead>
7470       <tbody>
7471        <row>
7472         <entry> <literal>&lt;</literal> </entry>
7473         <entry>is less than</entry>
7474         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
7475        </row>
7476        <row>
7477         <entry> <literal>&lt;=</literal> </entry>
7478         <entry>is less than or equal</entry>
7479         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
7480        </row>
7481        <row>
7482         <entry> <literal>=</literal> </entry>
7483         <entry>equals</entry>
7484         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
7485        </row>
7486        <row>
7487         <entry> <literal>&gt;=</literal> </entry>
7488         <entry>is greater or equal</entry>
7489         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
7490        </row>
7491        <row>
7492         <entry> <literal>&gt;</literal> </entry>
7493         <entry>is greater than</entry>
7494         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
7495        </row>
7496        <row>
7497         <entry> <literal>&lt;&gt;</literal> </entry>
7498         <entry>is not equal</entry>
7499         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
7500        </row>
7501        <row>
7502         <entry> <literal>&lt;&lt;</literal> </entry>
7503         <entry>is contained within</entry>
7504         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
7505        </row>
7506        <row>
7507         <entry> <literal>&lt;&lt;=</literal> </entry>
7508         <entry>is contained within or equals</entry>
7509         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
7510        </row>
7511        <row>
7512         <entry> <literal>&gt;&gt;</literal> </entry>
7513         <entry>contains</entry>
7514         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
7515        </row>
7516        <row>
7517         <entry> <literal>&gt;&gt;=</literal> </entry>
7518         <entry>contains or equals</entry>
7519         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
7520        </row>
7521        <row>
7522         <entry> <literal>~</literal> </entry>
7523         <entry>bitwise NOT</entry>
7524         <entry><literal>~ inet '192.168.1.6'</literal></entry>
7525        </row>
7526        <row>
7527         <entry> <literal>&amp;</literal> </entry>
7528         <entry>bitwise AND</entry>
7529         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
7530        </row>
7531        <row>
7532         <entry> <literal>|</literal> </entry>
7533         <entry>bitwise OR</entry>
7534         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
7535        </row>
7536        <row>
7537         <entry> <literal>+</literal> </entry>
7538         <entry>addition</entry>
7539         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
7540        </row>
7541        <row>
7542         <entry> <literal>-</literal> </entry>
7543         <entry>subtraction</entry>
7544         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
7545        </row>
7546        <row>
7547         <entry> <literal>-</literal> </entry>
7548         <entry>subtraction</entry>
7549         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
7550        </row>
7551       </tbody>
7552      </tgroup>
7553     </table>
7554
7555   <para>
7556    <xref linkend="cidr-inet-functions-table"> shows the functions
7557    available for use with the <type>cidr</type> and <type>inet</type>
7558    types.  The <function>abbrev</function>, <function>host</function>,
7559    and <function>text</function>
7560    functions are primarily intended to offer alternative display
7561    formats.
7562   </para>
7563
7564     <table id="cidr-inet-functions-table">
7565      <title><type>cidr</type> and <type>inet</type> Functions</title>
7566      <tgroup cols="5">
7567       <thead>
7568        <row>
7569         <entry>Function</entry>
7570         <entry>Return Type</entry>
7571         <entry>Description</entry>
7572         <entry>Example</entry>
7573         <entry>Result</entry>
7574        </row>
7575       </thead>
7576       <tbody>
7577        <row>
7578         <entry><literal><function>abbrev</function>(<type>inet</type>)</literal></entry>
7579         <entry><type>text</type></entry>
7580         <entry>abbreviated display format as text</entry>
7581         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
7582         <entry><literal>10.1.0.0/16</literal></entry>
7583        </row>
7584        <row>
7585         <entry><literal><function>abbrev</function>(<type>cidr</type>)</literal></entry>
7586         <entry><type>text</type></entry>
7587         <entry>abbreviated display format as text</entry>
7588         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
7589         <entry><literal>10.1/16</literal></entry>
7590        </row>
7591        <row>
7592         <entry><literal><function>broadcast</function>(<type>inet</type>)</literal></entry>
7593         <entry><type>inet</type></entry>
7594         <entry>broadcast address for network</entry>
7595         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
7596         <entry><literal>192.168.1.255/24</literal></entry>
7597        </row>
7598        <row>
7599         <entry><literal><function>family</function>(<type>inet</type>)</literal></entry>
7600         <entry><type>int</type></entry>
7601         <entry>extract family of address; <literal>4</literal> for IPv4,
7602          <literal>6</literal> for IPv6</entry>
7603         <entry><literal>family('::1')</literal></entry>
7604         <entry><literal>6</literal></entry>
7605        </row>
7606        <row>
7607         <entry><literal><function>host</function>(<type>inet</type>)</literal></entry>
7608         <entry><type>text</type></entry>
7609         <entry>extract IP address as text</entry>
7610         <entry><literal>host('192.168.1.5/24')</literal></entry>
7611         <entry><literal>192.168.1.5</literal></entry>
7612        </row>
7613        <row>
7614         <entry><literal><function>hostmask</function>(<type>inet</type>)</literal></entry>
7615         <entry><type>inet</type></entry>
7616         <entry>construct host mask for network</entry>
7617         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
7618         <entry><literal>0.0.0.3</literal></entry>
7619        </row>
7620        <row>
7621         <entry><literal><function>masklen</function>(<type>inet</type>)</literal></entry>
7622         <entry><type>int</type></entry>
7623         <entry>extract netmask length</entry>
7624         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
7625         <entry><literal>24</literal></entry>
7626        </row>
7627        <row>
7628         <entry><literal><function>netmask</function>(<type>inet</type>)</literal></entry>
7629         <entry><type>inet</type></entry>
7630         <entry>construct netmask for network</entry>
7631         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
7632         <entry><literal>255.255.255.0</literal></entry>
7633        </row>
7634        <row>
7635         <entry><literal><function>network</function>(<type>inet</type>)</literal></entry>
7636         <entry><type>cidr</type></entry>
7637         <entry>extract network part of address</entry>
7638         <entry><literal>network('192.168.1.5/24')</literal></entry>
7639         <entry><literal>192.168.1.0/24</literal></entry>
7640        </row>
7641        <row>
7642         <entry><literal><function>set_masklen</function>(<type>inet</type>, <type>int</type>)</literal></entry>
7643         <entry><type>inet</type></entry>
7644         <entry>set netmask length for <type>inet</type> value</entry>
7645         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
7646         <entry><literal>192.168.1.5/16</literal></entry>
7647        </row>
7648        <row>
7649         <entry><literal><function>set_masklen</function>(<type>cidr</type>, <type>int</type>)</literal></entry>
7650         <entry><type>cidr</type></entry>
7651         <entry>set netmask length for <type>cidr</type> value</entry>
7652         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
7653         <entry><literal>192.168.0.0/16</literal></entry>
7654        </row>
7655        <row>
7656         <entry><literal><function>text</function>(<type>inet</type>)</literal></entry>
7657         <entry><type>text</type></entry>
7658         <entry>extract IP address and netmask length as text</entry>
7659         <entry><literal>text(inet '192.168.1.5')</literal></entry>
7660         <entry><literal>192.168.1.5/32</literal></entry>
7661        </row>
7662       </tbody>
7663      </tgroup>
7664     </table>
7665
7666   <para>
7667    Any <type>cidr</> value can be cast to <type>inet</> implicitly
7668    or explicitly; therefore, the functions shown above as operating on
7669    <type>inet</> also work on <type>cidr</> values.  (Where there are
7670    separate functions for <type>inet</> and <type>cidr</>, it is because
7671    the behavior should be different for the two cases.)
7672    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
7673    When this is done, any bits to the right of the netmask are silently zeroed
7674    to create a valid <type>cidr</> value.
7675    In addition,
7676    you can cast a text value to <type>inet</> or <type>cidr</>
7677    using normal casting syntax: for example,
7678    <literal>inet(<replaceable>expression</>)</literal> or
7679    <literal><replaceable>colname</>::cidr</literal>.
7680   </para>
7681
7682   <para>
7683    <xref linkend="macaddr-functions-table"> shows the functions
7684    available for use with the <type>macaddr</type> type.  The function
7685    <literal><function>trunc</function>(<type>macaddr</type>)</literal> returns a MAC
7686    address with the last 3 bytes set to zero.  This can be used to
7687    associate the remaining prefix with a manufacturer.
7688   </para>
7689
7690     <table id="macaddr-functions-table">
7691      <title><type>macaddr</type> Functions</title>
7692      <tgroup cols="5">
7693       <thead>
7694        <row>
7695         <entry>Function</entry>
7696         <entry>Return Type</entry>
7697         <entry>Description</entry>
7698         <entry>Example</entry>
7699         <entry>Result</entry>
7700        </row>
7701       </thead>
7702       <tbody>
7703        <row>
7704         <entry><literal><function>trunc</function>(<type>macaddr</type>)</literal></entry>
7705         <entry><type>macaddr</type></entry>
7706         <entry>set last 3 bytes to zero</entry>
7707         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
7708         <entry><literal>12:34:56:00:00:00</literal></entry>
7709        </row>
7710       </tbody>
7711      </tgroup>
7712     </table>
7713
7714    <para>
7715     The <type>macaddr</type> type also supports the standard relational
7716     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
7717     lexicographical ordering.
7718    </para>
7719
7720   </sect1>
7721
7722
7723  <sect1 id="functions-textsearch">
7724   <title>Text Search Functions and Operators</title>
7725
7726    <indexterm zone="datatype-textsearch">
7727     <primary>full text search</primary>
7728     <secondary>functions and operators</secondary>
7729    </indexterm>
7730
7731    <indexterm zone="datatype-textsearch">
7732     <primary>text search</primary>
7733     <secondary>functions and operators</secondary>
7734    </indexterm>
7735
7736   <para>
7737    <xref linkend="textsearch-operators-table">,
7738    <xref linkend="textsearch-functions-table"> and
7739    <xref linkend="textsearch-functions-debug-table">
7740    summarize the functions and operators that are provided
7741    for full text searching.  See <xref linkend="textsearch"> for a detailed
7742    explanation of <productname>PostgreSQL</productname>'s text search
7743    facility.
7744   </para>
7745
7746     <table id="textsearch-operators-table">
7747      <title>Text Search Operators</title>
7748      <tgroup cols="4">
7749       <thead>
7750        <row>
7751         <entry>Operator</entry>
7752         <entry>Description</entry>
7753         <entry>Example</entry>
7754         <entry>Result</entry>
7755        </row>
7756       </thead>
7757       <tbody>
7758        <row>
7759         <entry> <literal>@@</literal> </entry>
7760         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
7761         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
7762         <entry><literal>t</literal></entry>
7763        </row>
7764        <row>
7765         <entry> <literal>@@@</literal> </entry>
7766         <entry>deprecated synonym for <literal>@@</></entry>
7767         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
7768         <entry><literal>t</literal></entry>
7769        </row>
7770        <row>
7771         <entry> <literal>||</literal> </entry>
7772         <entry>concatenate <type>tsvector</>s</entry>
7773         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
7774         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
7775        </row>
7776        <row>
7777         <entry> <literal>&amp;&amp;</literal> </entry>
7778         <entry>AND <type>tsquery</>s together</entry>
7779         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
7780         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
7781        </row>
7782        <row>
7783         <entry> <literal>||</literal> </entry>
7784         <entry>OR <type>tsquery</>s together</entry>
7785         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
7786         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
7787        </row>
7788        <row>
7789         <entry> <literal>!!</literal> </entry>
7790         <entry>negate a <type>tsquery</></entry>
7791         <entry><literal>!! 'cat'::tsquery</literal></entry>
7792         <entry><literal>!'cat'</literal></entry>
7793        </row>
7794        <row>
7795         <entry> <literal>@&gt;</literal> </entry>
7796         <entry><type>tsquery</> contains another ?</entry>
7797         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
7798         <entry><literal>f</literal></entry>
7799        </row>
7800        <row>
7801         <entry> <literal>&lt;@</literal> </entry>
7802         <entry><type>tsquery</> is contained in ?</entry>
7803         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
7804         <entry><literal>t</literal></entry>
7805        </row>
7806       </tbody>
7807      </tgroup>
7808     </table>
7809
7810     <note>
7811      <para>
7812       The <type>tsquery</> containment operators consider only the lexemes
7813       listed in the two queries, ignoring the combining operators.
7814      </para>
7815     </note>
7816
7817     <para>
7818      In addition to the operators shown in the table, the ordinary B-tree
7819      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
7820      for types <type>tsvector</> and <type>tsquery</>.  These are not very
7821      useful for text searching but allow, for example, unique indexes to be
7822      built on columns of these types.
7823     </para>
7824
7825     <table id="textsearch-functions-table">
7826      <title>Text Search Functions</title>
7827      <tgroup cols="5">
7828       <thead>
7829        <row>
7830         <entry>Function</entry>
7831         <entry>Return Type</entry>
7832         <entry>Description</entry>
7833         <entry>Example</entry>
7834         <entry>Result</entry>
7835        </row>
7836       </thead>
7837       <tbody>
7838        <row>
7839         <entry><literal><function>to_tsvector</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</literal></entry>
7840         <entry><type>tsvector</type></entry>
7841         <entry>reduce document text to <type>tsvector</></entry>
7842         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
7843         <entry><literal>'fat':2 'rat':3</literal></entry>
7844        </row>
7845        <row>
7846         <entry><literal><function>length</function>(<type>tsvector</>)</literal></entry>
7847         <entry><type>integer</type></entry>
7848         <entry>number of lexemes in <type>tsvector</></entry>
7849         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7850         <entry><literal>3</literal></entry>
7851        </row>
7852        <row>
7853         <entry><literal><function>setweight</function>(<type>tsvector</>, <type>"char"</>)</literal></entry>
7854         <entry><type>tsvector</type></entry>
7855         <entry>assign weight to each element of <type>tsvector</></entry>
7856         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
7857         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
7858        </row>
7859        <row>
7860         <entry><literal><function>strip</function>(<type>tsvector</>)</literal></entry>
7861         <entry><type>tsvector</type></entry>
7862         <entry>remove positions and weights from <type>tsvector</></entry>
7863         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7864         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
7865        </row>
7866        <row>
7867         <entry><literal><function>to_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7868         <entry><type>tsquery</type></entry>
7869         <entry>normalize words and convert to <type>tsquery</></entry>
7870         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
7871         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7872        </row>
7873        <row>
7874         <entry><literal><function>plainto_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7875         <entry><type>tsquery</type></entry>
7876         <entry>produce <type>tsquery</> ignoring punctuation</entry>
7877         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
7878         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7879        </row>
7880        <row>
7881         <entry><literal><function>numnode</function>(<type>tsquery</>)</literal></entry>
7882         <entry><type>integer</type></entry>
7883         <entry>number of lexemes plus operators in <type>tsquery</></entry>
7884         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
7885         <entry><literal>5</literal></entry>
7886        </row>
7887        <row>
7888         <entry><literal><function>querytree</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</literal></entry>
7889         <entry><type>text</type></entry>
7890         <entry>get indexable part of a <type>tsquery</></entry>
7891         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
7892         <entry><literal>'foo'</literal></entry>
7893        </row>
7894        <row>
7895         <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>
7896         <entry><type>float4</type></entry>
7897         <entry>rank document for query</entry>
7898         <entry><literal>ts_rank(textsearch, query)</literal></entry>
7899         <entry><literal>0.818</literal></entry>
7900        </row>
7901        <row>
7902         <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>
7903         <entry><type>float4</type></entry>
7904         <entry>rank document for query using cover density</entry>
7905         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
7906         <entry><literal>2.01317</literal></entry>
7907        </row>
7908        <row>
7909         <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>
7910         <entry><type>text</type></entry>
7911         <entry>display a query match</entry>
7912         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
7913         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
7914        </row>
7915        <row>
7916         <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>
7917         <entry><type>tsquery</type></entry>
7918         <entry>replace target with substitute within query</entry>
7919         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
7920         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7921        </row>
7922        <row>
7923         <entry><literal><function>ts_rewrite</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</literal></entry>
7924         <entry><type>tsquery</type></entry>
7925         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
7926         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
7927         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7928        </row>
7929        <row>
7930         <entry><literal><function>get_current_ts_config</function>()</literal></entry>
7931         <entry><type>regconfig</type></entry>
7932         <entry>get default text search configuration</entry>
7933         <entry><literal>get_current_ts_config()</literal></entry>
7934         <entry><literal>english</literal></entry>
7935        </row>
7936        <row>
7937         <entry><literal><function>tsvector_update_trigger</function>()</literal></entry>
7938         <entry><type>trigger</type></entry>
7939         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7940         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
7941         <entry><literal></literal></entry>
7942        </row>
7943        <row>
7944         <entry><literal><function>tsvector_update_trigger_column</function>()</literal></entry>
7945         <entry><type>trigger</type></entry>
7946         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7947         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
7948         <entry><literal></literal></entry>
7949         <entry><literal></literal></entry>
7950        </row>
7951       </tbody>
7952      </tgroup>
7953     </table>
7954
7955   <note>
7956    <para>
7957     All the text search functions that accept an optional <type>regconfig</>
7958     argument will use the configuration specified by
7959     <xref linkend="guc-default-text-search-config">
7960     when that argument is omitted.
7961    </para>
7962   </note>
7963
7964   <para>
7965    The functions in
7966    <xref linkend="textsearch-functions-debug-table">
7967    are listed separately because they are not usually used in everyday text
7968    searching operations.  They are helpful for development and debugging
7969    of new text search configurations.
7970   </para>
7971
7972     <table id="textsearch-functions-debug-table">
7973      <title>Text Search Debugging Functions</title>
7974      <tgroup cols="5">
7975       <thead>
7976        <row>
7977         <entry>Function</entry>
7978         <entry>Return Type</entry>
7979         <entry>Description</entry>
7980         <entry>Example</entry>
7981         <entry>Result</entry>
7982        </row>
7983       </thead>
7984       <tbody>
7985        <row>
7986         <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>
7987         <entry><type>setof record</type></entry>
7988         <entry>test a configuration</entry>
7989         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
7990         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
7991        </row>
7992        <row>
7993         <entry><literal><function>ts_lexize</function>(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</literal></entry>
7994         <entry><type>text[]</type></entry>
7995         <entry>test a dictionary</entry>
7996         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
7997         <entry><literal>{star}</literal></entry>
7998        </row>
7999        <row>
8000         <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>
8001         <entry><type>setof record</type></entry>
8002         <entry>test a parser</entry>
8003         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
8004         <entry><literal>(1,foo) ...</literal></entry>
8005        </row>
8006        <row>
8007         <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>
8008         <entry><type>setof record</type></entry>
8009         <entry>test a parser</entry>
8010         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
8011         <entry><literal>(1,foo) ...</literal></entry>
8012        </row>
8013        <row>
8014         <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>
8015         <entry><type>setof record</type></entry>
8016         <entry>get token types defined by parser</entry>
8017         <entry><literal>ts_token_type('default')</literal></entry>
8018         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8019        </row>
8020        <row>
8021         <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>
8022         <entry><type>setof record</type></entry>
8023         <entry>get token types defined by parser</entry>
8024         <entry><literal>ts_token_type(3722)</literal></entry>
8025         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8026        </row>
8027        <row>
8028         <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>
8029         <entry><type>setof record</type></entry>
8030         <entry>get statistics of a <type>tsvector</> column</entry>
8031         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
8032         <entry><literal>(foo,10,15) ...</literal></entry>
8033        </row>
8034       </tbody>
8035      </tgroup>
8036     </table>
8037
8038  </sect1>
8039
8040
8041  <sect1 id="functions-xml">
8042   <title>XML Functions</title>
8043
8044   <para>
8045    The functions and function-like expressions described in this
8046    section operate on values of type <type>xml</type>.  Check <xref
8047    linkend="datatype-xml"> for information about the <type>xml</type>
8048    type.  The function-like expressions <function>xmlparse</function>
8049    and <function>xmlserialize</function> for converting to and from
8050    type <type>xml</type> are not repeated here.  Use of many of these
8051    functions requires the installation to have been built
8052    with <command>configure --with-libxml</>.
8053   </para>
8054
8055   <sect2>
8056    <title>Producing XML Content</title>
8057
8058    <para>
8059     A set of functions and function-like expressions are available for
8060     producing XML content from SQL data.  As such, they are
8061     particularly suitable for formatting query results into XML
8062     documents for processing in client applications.
8063    </para>
8064
8065    <sect3>
8066     <title><literal>xmlcomment</literal></title>
8067
8068     <indexterm>
8069      <primary>xmlcomment</primary>
8070     </indexterm>
8071
8072 <synopsis>
8073 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8074 </synopsis>
8075
8076     <para>
8077      The function <function>xmlcomment</function> creates an XML value
8078      containing an XML comment with the specified text as content.
8079      The text cannot contain <quote><literal>--</literal></quote> or end with a
8080      <quote><literal>-</literal></quote> so that the resulting construct is a valid
8081      XML comment.  If the argument is null, the result is null.
8082     </para>
8083
8084     <para>
8085      Example:
8086 <screen><![CDATA[
8087 SELECT xmlcomment('hello');
8088
8089   xmlcomment
8090 --------------
8091  <!--hello-->
8092 ]]></screen>
8093     </para>
8094    </sect3>
8095
8096    <sect3>
8097     <title><literal>xmlconcat</literal></title>
8098
8099     <indexterm>
8100      <primary>xmlconcat</primary>
8101     </indexterm>
8102
8103  <synopsis>
8104  <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8105  </synopsis>
8106  
8107     <para>
8108      The function <function>xmlconcat</function> concatenates a list
8109      of individual XML values to create a single value containing an
8110      XML content fragment.  Null values are omitted; the result is
8111      only null if there are no nonnull arguments.
8112     </para>
8113
8114     <para>
8115      Example:
8116 <screen><![CDATA[
8117 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8118
8119       xmlconcat
8120 ----------------------
8121  <abc/><bar>foo</bar>
8122 ]]></screen>
8123     </para>
8124
8125     <para>
8126      XML declarations, if present, are combined as follows.  If all
8127      argument values have the same XML version declaration, that
8128      version is used in the result, else no version is used.  If all
8129      argument values have the standalone declaration value
8130      <quote>yes</quote>, then that value is used in the result.  If
8131      all argument values have a standalone declaration value and at
8132      least one is <quote>no</quote>, then that is used in the result.
8133      Else the result will have no standalone declaration.  If the
8134      result is determined to require a standalone declaration but no
8135      version declaration, a version declaration with version 1.0 will
8136      be used because XML requires an XML declaration to contain a
8137      version declaration.  Encoding declarations are ignored and
8138      removed in all cases.
8139     </para>
8140
8141     <para>
8142      Example:
8143 <screen><![CDATA[
8144 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
8145
8146              xmlconcat
8147 -----------------------------------
8148  <?xml version="1.1"?><foo/><bar/>
8149 ]]></screen>
8150     </para>
8151    </sect3>
8152  
8153    <sect3>
8154     <title><literal>xmlelement</literal></title>
8155  
8156    <indexterm>
8157     <primary>xmlelement</primary>
8158    </indexterm>
8159  
8160 <synopsis>
8161  <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>)
8162  </synopsis>
8163  
8164     <para>
8165      The <function>xmlelement</function> expression produces an XML
8166      element with the given name, attributes, and content.
8167     </para>
8168
8169     <para>
8170      Examples:
8171 <screen><![CDATA[
8172 SELECT xmlelement(name foo);
8173
8174  xmlelement
8175 ------------
8176  <foo/>
8177
8178 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8179
8180     xmlelement
8181 ------------------
8182  <foo bar="xyz"/>
8183
8184 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8185
8186              xmlelement
8187 -------------------------------------
8188  <foo bar="2007-01-26">content</foo>
8189 ]]></screen>
8190     </para>
8191
8192     <para>
8193      Element and attribute names that are not valid XML names are
8194      escaped by replacing the offending characters by the sequence
8195      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8196      <replaceable>HHHH</replaceable> is the character's Unicode
8197      codepoint in hexadecimal notation.  For example:
8198 <screen><![CDATA[
8199 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
8200
8201             xmlelement
8202 ----------------------------------
8203  <foo_x0024_bar a_x0026_b="xyz"/>
8204 ]]></screen>
8205     </para>
8206
8207     <para>
8208      An explicit attribute name need not be specified if the attribute
8209      value is a column reference, in which case the column's name will
8210      be used as the attribute name by default.  In other cases, the
8211      attribute must be given an explicit name.  So this example is
8212      valid:
8213 <screen>
8214 CREATE TABLE test (a xml, b xml);
8215 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8216 </screen>
8217      But these are not:
8218 <screen>
8219 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8220 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8221 </screen>
8222     </para>
8223
8224     <para>
8225      Element content, if specified, will be formatted according to
8226      the data type.  If the content is itself of type <type>xml</type>,
8227      complex XML documents can be constructed.  For example:
8228 <screen><![CDATA[
8229 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8230                             xmlelement(name abc),
8231                             xmlcomment('test'),
8232                             xmlelement(name xyz));
8233
8234                   xmlelement
8235 ----------------------------------------------
8236  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
8237 ]]></screen>
8238
8239      Content of other types will be formatted into valid XML character
8240      data.  This means in particular that the characters &lt;, &gt;,
8241      and &amp; will be converted to entities.  Binary data (data type
8242      <type>bytea</type>) will be represented in base64 or hex
8243      encoding, depending on the setting of the configuration parameter
8244      <xref linkend="guc-xmlbinary">.  The particular behavior for
8245      individual data types is expected to evolve in order to align the
8246      SQL and PostgreSQL data types with the XML Schema specification,
8247      at which point a more precise description will appear.
8248     </para>
8249    </sect3>
8250  
8251    <sect3>
8252     <title><literal>xmlforest</literal></title>
8253  
8254    <indexterm>
8255     <primary>xmlforest</primary>
8256    </indexterm>
8257  
8258  <synopsis>
8259  <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8260  </synopsis>
8261  
8262     <para>
8263      The <function>xmlforest</function> expression produces an XML
8264      forest (sequence) of elements using the given names and content.
8265     </para>
8266
8267     <para>
8268      Examples:
8269 <screen><![CDATA[
8270 SELECT xmlforest('abc' AS foo, 123 AS bar);
8271
8272           xmlforest
8273 ------------------------------
8274  <foo>abc</foo><bar>123</bar>
8275
8276
8277 SELECT xmlforest(table_name, column_name)
8278 FROM information_schema.columns
8279 WHERE table_schema = 'pg_catalog';
8280
8281                                          xmlforest
8282 -------------------------------------------------------------------------------------------
8283  <table_name>pg_authid</table_name><column_name>rolname</column_name>
8284  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8285  ...
8286 ]]></screen>
8287
8288      As seen in the second example, the element name can be omitted if
8289      the content value is a column reference, in which case the column
8290      name is used by default.  Otherwise, a name must be specified.
8291     </para>
8292
8293     <para>
8294      Element names that are not valid XML names are escaped as shown
8295      for <function>xmlelement</function> above.  Similarly, content
8296      data is escaped to make valid XML content, unless it is already
8297      of type <type>xml</type>.
8298     </para>
8299
8300     <para>
8301      Note that XML forests are not valid XML documents if they consist
8302      of more than one element, so it might be useful to wrap
8303      <function>xmlforest</function> expressions in
8304      <function>xmlelement</function>.
8305     </para>
8306    </sect3>
8307  
8308    <sect3>
8309     <title><literal>xmlpi</literal></title>
8310  
8311    <indexterm>
8312     <primary>xmlpi</primary>
8313    </indexterm>
8314  
8315  <synopsis>
8316  <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
8317  </synopsis>
8318  
8319     <para>
8320      The <function>xmlpi</function> expression creates an XML
8321      processing instruction.  The content, if present, must not
8322      contain the character sequence <literal>?&gt;</literal>.
8323     </para>
8324
8325     <para>
8326      Example:
8327 <screen><![CDATA[
8328 SELECT xmlpi(name php, 'echo "hello world";');
8329
8330             xmlpi
8331 -----------------------------
8332  <?php echo "hello world";?>
8333 ]]></screen>
8334     </para>
8335    </sect3>
8336  
8337    <sect3>
8338     <title><literal>xmlroot</literal></title>
8339  
8340    <indexterm>
8341     <primary>xmlroot</primary>
8342    </indexterm>
8343  
8344  <synopsis>
8345  <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
8346  </synopsis>
8347  
8348     <para>
8349      The <function>xmlroot</function> expression alters the properties
8350      of the root node of an XML value.  If a version is specified,
8351      this replaces the value in the version declaration;  if a
8352      standalone value is specified, this replaces the value in the
8353      standalone declaration.
8354     </para>
8355
8356     <para>
8357 <screen><![CDATA[
8358 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'), 
8359                version '1.0', standalone yes);
8360
8361                 xmlroot
8362 ----------------------------------------
8363  <?xml version="1.0" standalone="yes"?>
8364  <content>abc</content>
8365 ]]></screen>
8366     </para>
8367    </sect3>
8368
8369    <sect3 id="functions-xml-xmlagg">
8370     <title><literal>xmlagg</literal></title>
8371
8372     <indexterm>
8373      <primary>xmlagg</primary>
8374     </indexterm>
8375
8376 <synopsis>
8377 <function>xmlagg</function>(<replaceable>xml</replaceable>)
8378 </synopsis>
8379
8380     <para>
8381      The function <function>xmlagg</function> is, unlike the other
8382      functions described here, an aggregate function.  It concatenates the
8383      input values to the aggregate function call,
8384      like <function>xmlconcat</function> does.
8385      See <xref linkend="functions-aggregate"> for additional information
8386      about aggregate functions.
8387     </para>
8388
8389     <para>
8390      Example:
8391 <screen><![CDATA[
8392 CREATE TABLE test (y int, x xml);
8393 INSERT INTO test VALUES (1, '<foo>abc</foo>');
8394 INSERT INTO test VALUES (2, '<bar/>');
8395 SELECT xmlagg(x) FROM test;
8396         xmlagg
8397 ----------------------
8398  <foo>abc</foo><bar/>
8399 ]]></screen>
8400     </para>
8401
8402     <para>
8403      To determine the order of the concatenation, something like the
8404      following approach can be used:
8405
8406 <screen><![CDATA[
8407 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
8408         xmlagg
8409 ----------------------
8410  <bar/><foo>abc</foo>
8411 ]]></screen>
8412
8413      Again, see <xref linkend="functions-aggregate"> for additional
8414      information.
8415     </para>
8416    </sect3>
8417
8418    <sect3>
8419     <title>XML Predicates</title>
8420
8421     <indexterm>
8422      <primary>IS DOCUMENT</primary>
8423     </indexterm>
8424
8425 <synopsis>
8426 <replaceable>xml</replaceable> IS DOCUMENT
8427 </synopsis>
8428
8429     <para>
8430      The expression <literal>IS DOCUMENT</literal> returns true if the
8431      argument XML value is a proper XML document, false if it is not
8432      (that is, it is a content fragment), or null if the argument is
8433      null.  See <xref linkend="datatype-xml"> about the difference
8434      between documents and content fragments.
8435     </para>
8436    </sect3>
8437   </sect2>
8438
8439   <sect2 id="functions-xml-processing">
8440    <title>Processing XML</title>
8441
8442    <indexterm>
8443     <primary>XPath</primary>
8444    </indexterm>
8445
8446    <para>
8447     To process values of data type <type>xml</type>, PostgreSQL offers
8448     the function <function>xpath</function>, which evaluates XPath 1.0
8449     expressions.
8450    </para>
8451
8452 <synopsis>
8453 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable><optional>, <replaceable>nsarray</replaceable></optional>)
8454 </synopsis>
8455
8456    <para>
8457     The function <function>xpath</function> evaluates the XPath
8458     expression <replaceable>xpath</replaceable> against the XML value
8459     <replaceable>xml</replaceable>.  It returns an array of XML values
8460     corresponding to the node set produced by the XPath expression.
8461    </para>
8462
8463   <para>
8464     The second argument must be a well formed XML document. In particular,
8465     it must have a single root node element.
8466   </para>
8467
8468    <para>
8469     The third argument of the function is an array of namespace
8470     mappings.  This array should be a two-dimensional array with the
8471     length of the second axis being equal to 2 (i.e., it should be an
8472     array of arrays, each of which consists of exactly 2 elements).
8473     The first element of each array entry is the namespace name, the
8474     second the namespace URI.
8475    </para>
8476
8477    <para>
8478     Example:
8479 <screen><![CDATA[
8480 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', 
8481              ARRAY[ARRAY['my', 'http://example.com']]);
8482
8483  xpath  
8484 --------
8485  {test}
8486 (1 row)
8487 ]]></screen>
8488    </para>
8489   </sect2>
8490
8491   <sect2 id="functions-xml-mapping">
8492    <title>Mapping Tables to XML</title>
8493
8494    <indexterm zone="functions-xml-mapping"> 
8495     <primary>XML export</primary>
8496    </indexterm>
8497
8498    <para>
8499     The following functions map the contents of relational tables to
8500     XML values.  They can be thought of as XML export functionality:
8501 <synopsis>
8502 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8503 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
8504 cursor_to_xml(cursor refcursor, count int, nulls boolean, 
8505               tableforest boolean, targetns text)
8506 </synopsis>
8507     The return type of each function is <type>xml</type>.
8508    </para>
8509
8510    <para>
8511     <function>table_to_xml</function> maps the content of the named
8512     table, passed as parameter <parameter>tbl</parameter>.  The
8513     <type>regclass</type> type accepts strings identifying tables using the
8514     usual notation, including optional schema qualifications and
8515     double quotes.  <function>query_to_xml</function> executes the
8516     query whose text is passed as parameter
8517     <parameter>query</parameter> and maps the result set.
8518     <function>cursor_to_xml</function> fetches the indicated number of
8519     rows from the cursor specified by the parameter
8520     <parameter>cursor</parameter>.  This variant is recommended if
8521     large tables have to be mapped, because the result value is built
8522     up in memory by each function.
8523    </para>
8524
8525    <para>
8526     If <parameter>tableforest</parameter> is false, then the resulting
8527     XML document looks like this:
8528 <screen><![CDATA[
8529 <tablename>
8530   <row>
8531     <columnname1>data</columnname1>
8532     <columnname2>data</columnname2>
8533   </row>
8534
8535   <row>
8536     ...
8537   </row>
8538
8539   ...
8540 </tablename>
8541 ]]></screen>
8542
8543     If <parameter>tableforest</parameter> is true, the result is an
8544     XML content fragment that looks like this:
8545 <screen><![CDATA[
8546 <tablename>
8547   <columnname1>data</columnname1>
8548   <columnname2>data</columnname2>
8549 </tablename>
8550
8551 <tablename>
8552   ...
8553 </tablename>
8554
8555 ...
8556 ]]></screen>
8557
8558     If no table name is available, that is, when mapping a query or a
8559     cursor, the string <literal>table</literal> is used in the first
8560     format, <literal>row</literal> in the second format.
8561    </para>
8562
8563    <para>
8564     The choice between these formats is up to the user.  The first
8565     format is a proper XML document, which will be important in many
8566     applications.  The second format tends to be more useful in the
8567     <function>cursor_to_xml</function> function if the result values are to be
8568     reassembled into one document later on.  The functions for
8569     producing XML content discussed above, in particular
8570     <function>xmlelement</function>, can be used to alter the results
8571     to taste.
8572    </para>
8573
8574    <para>
8575     The data values are mapped in the same way as described for the
8576     function <function>xmlelement</function> above.
8577    </para>
8578
8579    <para>
8580     The parameter <parameter>nulls</parameter> determines whether null
8581     values should be included in the output.  If true, null values in
8582     columns are represented as:
8583 <screen><![CDATA[
8584 <columnname xsi:nil="true"/>
8585 ]]></screen>
8586     where <literal>xsi</literal> is the XML namespace prefix for XML
8587     Schema Instance.  An appropriate namespace declaration will be
8588     added to the result value.  If false, columns containing null
8589     values are simply omitted from the output.
8590    </para>
8591
8592    <para>
8593     The parameter <parameter>targetns</parameter> specifies the
8594     desired XML namespace of the result.  If no particular namespace
8595     is wanted, an empty string should be passed.
8596    </para>
8597
8598    <para>
8599     The following functions return XML Schema documents describing the
8600     mappings performed by the corresponding functions above:
8601 <synopsis>
8602 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8603 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8604 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
8605 </synopsis>
8606     It is essential that the same parameters are passed in order to
8607     obtain matching XML data mappings and XML Schema documents.
8608    </para>
8609
8610    <para>
8611     The following functions produce XML data mappings and the
8612     corresponding XML Schema in one document (or forest), linked
8613     together.  They can be useful where self-contained and
8614     self-describing results are wanted:
8615 <synopsis>
8616 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8617 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8618 </synopsis>
8619    </para>
8620
8621    <para>
8622     In addition, the following functions are available to produce
8623     analogous mappings of entire schemas or the entire current
8624     database:
8625 <synopsis>
8626 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
8627 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8628 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8629
8630 database_to_xml(nulls boolean, tableforest boolean, targetns text)
8631 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
8632 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
8633 </synopsis>
8634
8635     Note that these potentially produce a lot of data, which needs to
8636     be built up in memory.  When requesting content mappings of large
8637     schemas or databases, it might be worthwhile to consider mapping the
8638     tables separately instead, possibly even through a cursor.
8639    </para>
8640
8641    <para>
8642     The result of a schema content mapping looks like this:
8643
8644 <screen><![CDATA[
8645 <schemaname>
8646
8647 table1-mapping
8648
8649 table2-mapping
8650
8651 ...
8652
8653 </schemaname>]]></screen>
8654
8655     where the format of a table mapping depends on the
8656     <parameter>tableforest</parameter> parameter as explained above.
8657    </para>
8658
8659    <para>
8660     The result of a database content mapping looks like this:
8661
8662 <screen><![CDATA[
8663 <dbname>
8664
8665 <schema1name>
8666   ...
8667 </schema1name>
8668
8669 <schema2name>
8670   ...
8671 </schema2name>
8672
8673 ...
8674
8675 </dbname>]]></screen>
8676
8677     where the schema mapping is as above.
8678    </para>
8679
8680    <para>
8681     As an example of using the output produced by these functions,
8682     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
8683     converts the output of
8684     <function>table_to_xml_and_xmlschema</function> to an HTML
8685     document containing a tabular rendition of the table data.  In a
8686     similar manner, the results from these functions can be
8687     converted into other XML-based formats.
8688    </para>
8689
8690    <figure id="xslt-xml-html">
8691     <title>XSLT stylesheet for converting SQL/XML output to HTML</title>
8692 <programlisting><![CDATA[
8693 <?xml version="1.0"?>
8694 <xsl:stylesheet version="1.0"
8695     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
8696     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
8697     xmlns="http://www.w3.org/1999/xhtml"
8698 >
8699
8700   <xsl:output method="xml"
8701       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
8702       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
8703       indent="yes"/>
8704
8705   <xsl:template match="/*">
8706     <xsl:variable name="schema" select="//xsd:schema"/>
8707     <xsl:variable name="tabletypename"
8708                   select="$schema/xsd:element[@name=name(current())]/@type"/>
8709     <xsl:variable name="rowtypename"
8710                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
8711
8712     <html>
8713       <head>
8714         <title><xsl:value-of select="name(current())"/></title>
8715       </head>
8716       <body>
8717         <table>
8718           <tr>
8719             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
8720               <th><xsl:value-of select="."/></th>
8721             </xsl:for-each>
8722           </tr>
8723
8724           <xsl:for-each select="row">
8725             <tr>
8726               <xsl:for-each select="*">
8727                 <td><xsl:value-of select="."/></td>
8728               </xsl:for-each>
8729             </tr>
8730           </xsl:for-each>
8731         </table>
8732       </body>
8733     </html>
8734   </xsl:template>
8735
8736 </xsl:stylesheet>
8737 ]]></programlisting>
8738    </figure>
8739   </sect2>
8740  </sect1>
8741
8742
8743  <sect1 id="functions-sequence">
8744   <title>Sequence Manipulation Functions</title>
8745
8746   <indexterm>
8747    <primary>sequence</primary>
8748   </indexterm>
8749   <indexterm>
8750    <primary>nextval</primary>
8751   </indexterm>
8752   <indexterm>
8753    <primary>currval</primary>
8754   </indexterm>
8755   <indexterm>
8756    <primary>lastval</primary>
8757   </indexterm>
8758   <indexterm>
8759    <primary>setval</primary>
8760   </indexterm>
8761
8762   <para>
8763    This section describes <productname>PostgreSQL</productname>'s
8764    functions for operating on <firstterm>sequence objects</firstterm>.
8765    Sequence objects (also called sequence generators or just
8766    sequences) are special single-row tables created with <xref
8767    linkend="sql-createsequence" endterm="sql-createsequence-title">.
8768    A sequence object is usually used to generate unique identifiers
8769    for rows of a table.  The sequence functions, listed in <xref
8770    linkend="functions-sequence-table">, provide simple, multiuser-safe
8771    methods for obtaining successive sequence values from sequence
8772    objects.
8773   </para>
8774
8775    <table id="functions-sequence-table">
8776     <title>Sequence Functions</title>
8777     <tgroup cols="3">
8778      <thead>
8779       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
8780      </thead>
8781
8782      <tbody>
8783       <row>
8784         <entry><literal><function>currval</function>(<type>regclass</type>)</literal></entry>
8785         <entry><type>bigint</type></entry>
8786         <entry>Return value most recently obtained with
8787         <function>nextval</function> for specified sequence</entry>
8788       </row>
8789       <row>
8790         <entry><literal><function>lastval</function>()</literal></entry>
8791         <entry><type>bigint</type></entry>
8792         <entry>Return value most recently obtained with
8793         <function>nextval</function> for any sequence</entry>
8794       </row>
8795       <row>
8796         <entry><literal><function>nextval</function>(<type>regclass</type>)</literal></entry>
8797         <entry><type>bigint</type></entry>
8798         <entry>Advance sequence and return new value</entry>
8799       </row>
8800       <row>
8801         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>)</literal></entry>
8802         <entry><type>bigint</type></entry>
8803         <entry>Set sequence's current value</entry>
8804       </row>
8805       <row>
8806         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</literal></entry>
8807         <entry><type>bigint</type></entry>
8808         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
8809       </row>
8810      </tbody>
8811     </tgroup>
8812    </table>
8813
8814   <para>
8815    The sequence to be operated on by a sequence function is specified by
8816    a <type>regclass</> argument, which is simply the OID of the sequence in the
8817    <structname>pg_class</> system catalog.  You do not have to look up the
8818    OID by hand, however, since the <type>regclass</> data type's input
8819    converter will do the work for you.  Just write the sequence name enclosed
8820    in single quotes so that it looks like a literal constant.  For
8821    compatibility with the handling of ordinary
8822    <acronym>SQL</acronym> names, the string will be converted to lowercase
8823    unless it contains double quotes around the sequence name.  Thus:
8824 <programlisting>
8825 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
8826 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
8827 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
8828 </programlisting>
8829    The sequence name can be schema-qualified if necessary:
8830 <programlisting>
8831 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
8832 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
8833 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
8834 </programlisting>
8835    See <xref linkend="datatype-oid"> for more information about
8836    <type>regclass</>.
8837   </para>
8838
8839   <note>
8840    <para>
8841     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
8842     sequence functions were of type <type>text</>, not <type>regclass</>, and
8843     the above-described conversion from a text string to an OID value would
8844     happen at run time during each call.  For backwards compatibility, this
8845     facility still exists, but internally it is now handled as an implicit
8846     coercion from <type>text</> to <type>regclass</> before the function is
8847     invoked.
8848    </para>
8849
8850    <para>
8851     When you write the argument of a sequence function as an unadorned
8852     literal string, it becomes a constant of type <type>regclass</>.
8853     Since this is really just an OID, it will track the originally
8854     identified sequence despite later renaming, schema reassignment,
8855     etc.  This <quote>early binding</> behavior is usually desirable for
8856     sequence references in column defaults and views.  But sometimes you might
8857     want <quote>late binding</> where the sequence reference is resolved
8858     at run time.  To get late-binding behavior, force the constant to be
8859     stored as a <type>text</> constant instead of <type>regclass</>:
8860 <programlisting>
8861 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
8862 </programlisting>
8863     Note that late binding was the only behavior supported in
8864     <productname>PostgreSQL</productname> releases before 8.1, so you
8865     might need to do this to preserve the semantics of old applications.
8866    </para>
8867
8868    <para>
8869     Of course, the argument of a sequence function can be an expression
8870     as well as a constant.  If it is a text expression then the implicit
8871     coercion will result in a run-time lookup.
8872    </para>
8873   </note>
8874
8875   <para>
8876    The available sequence functions are:
8877
8878     <variablelist>
8879      <varlistentry>
8880       <term><function>nextval</function></term>
8881       <listitem>
8882        <para>
8883         Advance the sequence object to its next value and return that
8884         value.  This is done atomically: even if multiple sessions
8885         execute <function>nextval</function> concurrently, each will safely receive
8886         a distinct sequence value.
8887        </para>
8888       </listitem>
8889      </varlistentry>
8890
8891      <varlistentry>
8892       <term><function>currval</function></term>
8893       <listitem>
8894        <para>
8895         Return the value most recently obtained by <function>nextval</function>
8896         for this sequence in the current session.  (An error is
8897         reported if <function>nextval</function> has never been called for this
8898         sequence in this session.)  Because this is returning
8899         a session-local value, it gives a predictable answer whether or not
8900         other sessions have executed <function>nextval</function> since the
8901         current session did.
8902        </para>
8903       </listitem>
8904      </varlistentry>
8905
8906      <varlistentry>
8907       <term><function>lastval</function></term>
8908       <listitem>
8909        <para>
8910         Return the value most recently returned by
8911         <function>nextval</> in the current session. This function is
8912         identical to <function>currval</function>, except that instead
8913         of taking the sequence name as an argument it fetches the
8914         value of the last sequence used by <function>nextval</function>
8915         in the current session. It is an error to call
8916         <function>lastval</function> if <function>nextval</function>
8917         has not yet been called in the current session.
8918        </para>
8919       </listitem>
8920      </varlistentry>
8921
8922      <varlistentry>
8923       <term><function>setval</function></term>
8924       <listitem>
8925        <para>
8926         Reset the sequence object's counter value.  The two-parameter
8927         form sets the sequence's <literal>last_value</literal> field to the
8928         specified value and sets its <literal>is_called</literal> field to
8929         <literal>true</literal>, meaning that the next
8930         <function>nextval</function> will advance the sequence before
8931         returning a value.  The value reported by <function>currval</> is
8932         also set to the specified value.  In the three-parameter form,
8933         <literal>is_called</literal> can be set to either <literal>true</literal>
8934         or <literal>false</literal>.  <literal>true</> has the same effect as
8935         the two-parameter form. If it is set to <literal>false</literal>, the
8936         next <function>nextval</function> will return exactly the specified
8937         value, and sequence advancement commences with the following
8938         <function>nextval</function>.  Furthermore, the value reported by
8939         <function>currval</> is not changed in this case (this is a change
8940         from pre-8.3 behavior).  For example,
8941
8942 <screen>
8943 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
8944 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
8945 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
8946 </screen>
8947
8948         The result returned by <function>setval</function> is just the value of its
8949         second argument.
8950        </para>
8951       </listitem>
8952      </varlistentry>
8953     </variablelist>
8954   </para>
8955
8956   <para>
8957    If a sequence object has been created with default parameters,
8958    <function>nextval</function> will return successive values
8959    beginning with 1.  Other behaviors can be obtained by using
8960    special parameters in the <xref linkend="sql-createsequence" endterm="sql-createsequence-title"> command;
8961    see its command reference page for more information.
8962   </para>
8963
8964   <important>
8965    <para>
8966     To avoid blocking concurrent transactions that obtain numbers from the
8967     same sequence, a <function>nextval</function> operation is never rolled back;
8968     that is, once a value has been fetched it is considered used, even if the
8969     transaction that did the <function>nextval</function> later aborts.  This means
8970     that aborted transactions might leave unused <quote>holes</quote> in the
8971     sequence of assigned values.  <function>setval</function> operations are never
8972     rolled back, either.
8973    </para>
8974   </important>
8975
8976  </sect1>
8977
8978
8979  <sect1 id="functions-conditional">
8980   <title>Conditional Expressions</title>
8981
8982   <indexterm>
8983    <primary>CASE</primary>
8984   </indexterm>
8985
8986   <indexterm>
8987    <primary>conditional expression</primary>
8988   </indexterm>
8989
8990   <para>
8991    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
8992    available in <productname>PostgreSQL</productname>.
8993   </para>
8994
8995   <tip>
8996    <para>
8997     If your needs go beyond the capabilities of these conditional
8998     expressions, you might want to consider writing a stored procedure
8999     in a more expressive programming language.
9000    </para>
9001   </tip>
9002
9003   <sect2>
9004    <title><literal>CASE</></title>
9005
9006   <para>
9007    The <acronym>SQL</acronym> <token>CASE</token> expression is a
9008    generic conditional expression, similar to if/else statements in
9009    other programming languages:
9010
9011 <synopsis>
9012 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
9013      <optional>WHEN ...</optional>
9014      <optional>ELSE <replaceable>result</replaceable></optional>
9015 END
9016 </synopsis>
9017
9018    <token>CASE</token> clauses can be used wherever
9019    an expression is valid.  <replaceable>condition</replaceable> is an
9020    expression that returns a <type>boolean</type> result.  If the result is true
9021    the value of the <token>CASE</token> expression is the
9022    <replaceable>result</replaceable> that follows the condition.  If the result is false
9023    subsequent <token>WHEN</token> clauses are searched in the same
9024    manner.  If no <token>WHEN</token>
9025    <replaceable>condition</replaceable> is true then the value of the
9026    case expression is the <replaceable>result</replaceable> of the
9027    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
9028    omitted and no condition matches, the result is null.
9029   </para>
9030
9031    <para>
9032     An example:
9033 <screen>
9034 SELECT * FROM test;
9035
9036  a
9037 ---
9038  1
9039  2
9040  3
9041
9042
9043 SELECT a,
9044        CASE WHEN a=1 THEN 'one'
9045             WHEN a=2 THEN 'two'
9046             ELSE 'other'
9047        END
9048     FROM test;
9049
9050  a | case
9051 ---+-------
9052  1 | one
9053  2 | two
9054  3 | other
9055 </screen>
9056    </para>
9057
9058   <para>
9059    The data types of all the <replaceable>result</replaceable>
9060    expressions must be convertible to a single output type.
9061    See <xref linkend="typeconv-union-case"> for more details.
9062   </para>
9063
9064   <para>
9065    The following <token>CASE</token> expression is a
9066    variant of the general form above:
9067
9068 <synopsis>
9069 CASE <replaceable>expression</replaceable>
9070     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
9071     <optional>WHEN ...</optional>
9072     <optional>ELSE <replaceable>result</replaceable></optional>
9073 END
9074 </synopsis>
9075
9076    The
9077    <replaceable>expression</replaceable> is computed and compared to
9078    all the <replaceable>value</replaceable>s in the
9079    <token>WHEN</token> clauses until one is found that is equal.  If
9080    no match is found, the <replaceable>result</replaceable> of the
9081    <token>ELSE</token> clause (or a null value) is returned.  This is similar
9082    to the <function>switch</function> statement in C.
9083   </para>
9084
9085    <para>
9086     The example above can be written using the simple
9087     <token>CASE</token> syntax:
9088 <screen>
9089 SELECT a,
9090        CASE a WHEN 1 THEN 'one'
9091               WHEN 2 THEN 'two'
9092               ELSE 'other'
9093        END
9094     FROM test;
9095
9096  a | case
9097 ---+-------
9098  1 | one
9099  2 | two
9100  3 | other
9101 </screen>
9102    </para>
9103
9104    <para>
9105     A <token>CASE</token> expression evaluates any subexpressions
9106     that are needed to determine the result.  For example, this is a
9107     possible way of avoiding a division-by-zero failure:
9108 <programlisting>
9109 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
9110 </programlisting>
9111    </para>
9112   </sect2>
9113
9114   <sect2>
9115    <title><literal>COALESCE</></title>
9116
9117   <indexterm>
9118    <primary>COALESCE</primary>
9119   </indexterm>
9120
9121   <indexterm>
9122    <primary>NVL</primary>
9123   </indexterm>
9124
9125   <indexterm>
9126    <primary>IFNULL</primary>
9127   </indexterm>
9128
9129 <synopsis>
9130 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9131 </synopsis>
9132
9133   <para>
9134    The <function>COALESCE</function> function returns the first of its
9135    arguments that is not null.  Null is returned only if all arguments
9136    are null.  It is often used to substitute a default value for 
9137    null values when data is retrieved for display, for example:
9138 <programlisting>
9139 SELECT COALESCE(description, short_description, '(none)') ...
9140 </programlisting>
9141   </para>
9142
9143    <para>
9144     Like a <token>CASE</token> expression, <function>COALESCE</function> only
9145     evaluates arguments that are needed to determine the result;
9146     that is, arguments to the right of the first non-null argument are
9147     not evaluated.  This SQL-standard function provides capabilities similar
9148     to <function>NVL</> and <function>IFNULL</>, which are used in some other
9149     database systems.
9150    </para>
9151   </sect2>
9152
9153   <sect2>
9154    <title><literal>NULLIF</></title>
9155
9156   <indexterm>
9157    <primary>NULLIF</primary>
9158   </indexterm>
9159
9160 <synopsis>
9161 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
9162 </synopsis>
9163
9164   <para>
9165    The <function>NULLIF</function> function returns a null value if
9166    <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
9167    otherwise it returns <replaceable>value1</replaceable>.
9168    This can be used to perform the inverse operation of the
9169    <function>COALESCE</function> example given above:
9170 <programlisting>
9171 SELECT NULLIF(value, '(none)') ...
9172 </programlisting>
9173   </para>
9174   <para>
9175    If <replaceable>value1</replaceable> is <literal>(none)</>, return a null,
9176    otherwise return <replaceable>value1</replaceable>.
9177   </para>
9178
9179   </sect2>
9180
9181   <sect2>
9182    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
9183
9184   <indexterm>
9185    <primary>GREATEST</primary>
9186   </indexterm>
9187   <indexterm>
9188    <primary>LEAST</primary>
9189   </indexterm>
9190
9191 <synopsis>
9192 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9193 </synopsis>
9194 <synopsis>
9195 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9196 </synopsis>
9197
9198    <para>
9199     The <function>GREATEST</> and <function>LEAST</> functions select the
9200     largest or smallest value from a list of any number of expressions.
9201     The expressions must all be convertible to a common data type, which
9202     will be the type of the result
9203     (see <xref linkend="typeconv-union-case"> for details).  NULL values
9204     in the list are ignored.  The result will be NULL only if all the
9205     expressions evaluate to NULL.
9206    </para>
9207
9208    <para>
9209     Note that <function>GREATEST</> and <function>LEAST</> are not in
9210     the SQL standard, but are a common extension.  Some other databases
9211     make them return NULL if any argument is NULL, rather than only when
9212     all are NULL.
9213    </para>
9214   </sect2>
9215  </sect1>
9216
9217  <sect1 id="functions-array">
9218   <title>Array Functions and Operators</title>
9219
9220   <para>
9221    <xref linkend="array-operators-table"> shows the operators
9222    available for array types.
9223   </para>
9224
9225     <table id="array-operators-table">
9226      <title>Array Operators</title>
9227      <tgroup cols="4">
9228       <thead>
9229        <row>
9230         <entry>Operator</entry>
9231         <entry>Description</entry>
9232         <entry>Example</entry>
9233         <entry>Result</entry>
9234        </row>
9235       </thead>
9236       <tbody>
9237        <row>
9238         <entry> <literal>=</literal> </entry>
9239         <entry>equal</entry>
9240         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
9241         <entry><literal>t</literal></entry>
9242        </row>
9243
9244        <row>
9245         <entry> <literal>&lt;&gt;</literal> </entry>
9246         <entry>not equal</entry>
9247         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
9248         <entry><literal>t</literal></entry>
9249        </row>
9250
9251        <row>
9252         <entry> <literal>&lt;</literal> </entry>
9253         <entry>less than</entry>
9254         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
9255         <entry><literal>t</literal></entry>
9256        </row>
9257
9258        <row>
9259         <entry> <literal>&gt;</literal> </entry>
9260         <entry>greater than</entry>
9261         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
9262         <entry><literal>t</literal></entry>
9263        </row>
9264
9265        <row>
9266         <entry> <literal>&lt;=</literal> </entry>
9267         <entry>less than or equal</entry>
9268         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
9269         <entry><literal>t</literal></entry>
9270        </row>
9271
9272        <row>
9273         <entry> <literal>&gt;=</literal> </entry>
9274         <entry>greater than or equal</entry>
9275         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
9276         <entry><literal>t</literal></entry>
9277        </row>
9278
9279        <row>
9280         <entry> <literal>@&gt;</literal> </entry>
9281         <entry>contains</entry>
9282         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
9283         <entry><literal>t</literal></entry>
9284        </row>
9285
9286        <row>
9287         <entry> <literal>&lt;@</literal> </entry>
9288         <entry>is contained by</entry>
9289         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
9290         <entry><literal>t</literal></entry>
9291        </row>
9292
9293        <row>
9294         <entry> <literal>&amp;&amp;</literal> </entry>
9295         <entry>overlap (have elements in common)</entry>
9296         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
9297         <entry><literal>t</literal></entry>
9298        </row>
9299
9300        <row>
9301         <entry> <literal>||</literal> </entry>
9302         <entry>array-to-array concatenation</entry>
9303         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
9304         <entry><literal>{1,2,3,4,5,6}</literal></entry>
9305        </row>
9306
9307        <row>
9308         <entry> <literal>||</literal> </entry>
9309         <entry>array-to-array concatenation</entry>
9310         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
9311         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
9312        </row>
9313
9314        <row>
9315         <entry> <literal>||</literal> </entry>
9316         <entry>element-to-array concatenation</entry>
9317         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
9318         <entry><literal>{3,4,5,6}</literal></entry>
9319        </row>
9320
9321        <row>
9322         <entry> <literal>||</literal> </entry>
9323         <entry>array-to-element concatenation</entry>
9324         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
9325         <entry><literal>{4,5,6,7}</literal></entry>
9326        </row>
9327       </tbody>
9328      </tgroup>
9329     </table>
9330
9331   <para>
9332    Array comparisons compare the array contents element-by-element,
9333    using the default B-Tree comparison function for the element data type.
9334    In multidimensional arrays the elements are visited in row-major order
9335    (last subscript varies most rapidly).
9336    If the contents of two arrays are equal but the dimensionality is
9337    different, the first difference in the dimensionality information
9338    determines the sort order.  (This is a change from versions of
9339    <productname>PostgreSQL</> prior to 8.2: older versions would claim
9340    that two arrays with the same contents were equal, even if the
9341    number of dimensions or subscript ranges were different.)
9342   </para>
9343
9344   <para>
9345    See <xref linkend="arrays"> for more details about array operator
9346    behavior.
9347   </para>
9348
9349   <para>
9350    <xref linkend="array-functions-table"> shows the functions
9351    available for use with array types. See <xref linkend="arrays">
9352    for more information  and examples of the use of these functions.
9353   </para>
9354
9355   <indexterm>
9356     <primary>array_append</primary>
9357   </indexterm>
9358   <indexterm>
9359     <primary>array_cat</primary>
9360   </indexterm>
9361   <indexterm>
9362     <primary>array_ndims</primary>
9363   </indexterm>
9364   <indexterm>
9365     <primary>array_dims</primary>
9366   </indexterm>
9367   <indexterm>
9368     <primary>array_fill</primary>
9369   </indexterm>
9370   <indexterm>
9371     <primary>array_length</primary>
9372   </indexterm>
9373   <indexterm>
9374     <primary>array_lower</primary>
9375   </indexterm>
9376   <indexterm>
9377     <primary>array_prepend</primary>
9378   </indexterm>
9379   <indexterm>
9380     <primary>array_to_string</primary>
9381   </indexterm>
9382  <indexterm>
9383     <primary>array_upper</primary>
9384   </indexterm>
9385   <indexterm>
9386     <primary>string_to_array</primary>
9387   </indexterm>
9388   <indexterm>
9389     <primary>unnest</primary>
9390   </indexterm>
9391
9392     <table id="array-functions-table">
9393      <title>Array Functions</title>
9394      <tgroup cols="5">
9395       <thead>
9396        <row>
9397         <entry>Function</entry>
9398         <entry>Return Type</entry>
9399         <entry>Description</entry>
9400         <entry>Example</entry>
9401         <entry>Result</entry>
9402        </row>
9403       </thead>
9404       <tbody>
9405        <row>
9406         <entry>
9407          <literal>
9408           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
9409          </literal>
9410         </entry>
9411         <entry><type>anyarray</type></entry>
9412         <entry>append an element to the end of an array</entry>
9413         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
9414         <entry><literal>{1,2,3}</literal></entry>
9415        </row>
9416        <row>
9417         <entry>
9418          <literal>
9419           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
9420          </literal>
9421         </entry>
9422         <entry><type>anyarray</type></entry>
9423         <entry>concatenate two arrays</entry>
9424         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
9425         <entry><literal>{1,2,3,4,5}</literal></entry>
9426        </row>
9427        <row>
9428         <entry>
9429          <literal>
9430           <function>array_ndims</function>(<type>anyarray</type>)
9431          </literal>
9432         </entry>
9433         <entry><type>int</type></entry>
9434         <entry>returns the number of dimensions of the array</entry>
9435         <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9436         <entry><literal>2</literal></entry>
9437        </row>
9438        <row>
9439         <entry>
9440          <literal>
9441           <function>array_dims</function>(<type>anyarray</type>)
9442          </literal>
9443         </entry>
9444         <entry><type>text</type></entry>
9445         <entry>returns a text representation of array's dimensions</entry>
9446         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9447         <entry><literal>[1:2][1:3]</literal></entry>
9448        </row>
9449        <row>
9450         <entry>
9451          <literal>
9452           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
9453           <optional>, <type>int[]</type></optional>)
9454          </literal>
9455         </entry>
9456         <entry><type>anyarray</type></entry>
9457         <entry>returns an array initialized with supplied value and
9458          dimensions, optionally with lower bounds other than 1</entry>
9459         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
9460         <entry><literal>[2:4]={7,7,7}</literal></entry>
9461        </row>
9462        <row>
9463         <entry>
9464          <literal>
9465           <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
9466          </literal>
9467         </entry>
9468         <entry><type>int</type></entry>
9469         <entry>returns the length of the requested array dimension</entry>
9470         <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
9471         <entry><literal>3</literal></entry>
9472        </row>
9473        <row>
9474         <entry>
9475          <literal>
9476           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
9477          </literal>
9478         </entry>
9479         <entry><type>int</type></entry>
9480         <entry>returns lower bound of the requested array dimension</entry>
9481         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
9482         <entry><literal>0</literal></entry>
9483        </row>
9484        <row>
9485         <entry>
9486          <literal>
9487           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
9488          </literal>
9489         </entry>
9490         <entry><type>anyarray</type></entry>
9491         <entry>append an element to the beginning of an array</entry>
9492         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
9493         <entry><literal>{1,2,3}</literal></entry>
9494        </row>
9495        <row>
9496         <entry>
9497          <literal>
9498           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type>)
9499          </literal>
9500         </entry>
9501         <entry><type>text</type></entry>
9502         <entry>concatenates array elements using supplied delimiter</entry>
9503         <entry><literal>array_to_string(ARRAY[1, 2, 3], '~^~')</literal></entry>
9504         <entry><literal>1~^~2~^~3</literal></entry>
9505        </row>
9506        <row>
9507         <entry>
9508          <literal>
9509           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
9510          </literal>
9511         </entry>
9512         <entry><type>int</type></entry>
9513         <entry>returns upper bound of the requested array dimension</entry>
9514         <entry><literal>array_upper(ARRAY[1,2,3,4], 1)</literal></entry>
9515         <entry><literal>4</literal></entry>
9516        </row>
9517        <row>
9518         <entry>
9519          <literal>
9520           <function>string_to_array</function>(<type>text</type>, <type>text</type>)
9521          </literal>
9522         </entry>
9523         <entry><type>text[]</type></entry>
9524         <entry>splits string into array elements using supplied delimiter</entry>
9525         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~')</literal></entry>
9526         <entry><literal>{xx,yy,zz}</literal></entry>
9527        </row>
9528        <row>
9529         <entry>
9530          <literal>
9531           <function>unnest</function>(<type>anyarray</type>)
9532          </literal>
9533         </entry>
9534         <entry><type>setof anyelement</type></entry>
9535         <entry>expand an array to a set of rows</entry>
9536         <entry><literal>unnest(ARRAY[1,2])</literal></entry>
9537         <entry><literal>1</literal><para><literal>2</literal></para> (2 rows)</entry>
9538        </row>
9539       </tbody>
9540      </tgroup>
9541     </table>
9542
9543    <para>
9544     See also <xref linkend="functions-aggregate"> about the aggregate
9545     function <function>array_agg</function> for use with arrays.
9546    </para>
9547   </sect1>
9548
9549  <sect1 id="functions-aggregate">
9550   <title>Aggregate Functions</title>
9551
9552   <indexterm zone="functions-aggregate">
9553    <primary>aggregate function</primary>
9554    <secondary>built-in</secondary>
9555   </indexterm>
9556
9557   <para>
9558    <firstterm>Aggregate functions</firstterm> compute a single result
9559    from a set of input values.  The built-in aggregate functions
9560    are listed in
9561    <xref linkend="functions-aggregate-table"> and
9562    <xref linkend="functions-aggregate-statistics-table">.
9563    The special syntax considerations for aggregate
9564    functions are explained in <xref linkend="syntax-aggregates">.
9565    Consult <xref linkend="tutorial-agg"> for additional introductory
9566    information.
9567   </para>
9568
9569   <table id="functions-aggregate-table">
9570    <title>General-Purpose Aggregate Functions</title>
9571
9572    <tgroup cols="4">
9573     <thead>
9574      <row>
9575       <entry>Function</entry>
9576       <entry>Argument Type</entry>
9577       <entry>Return Type</entry>
9578       <entry>Description</entry>
9579      </row>
9580     </thead>
9581
9582     <tbody>
9583      <row>
9584       <entry>
9585        <indexterm>
9586         <primary>array_agg</primary>
9587        </indexterm>
9588        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
9589       </entry>
9590       <entry>
9591        any
9592       </entry>
9593       <entry>
9594        array of the argument type
9595       </entry>
9596       <entry>input values concatenated into an array</entry>
9597      </row>
9598
9599      <row>
9600       <entry>
9601        <indexterm>
9602         <primary>average</primary>
9603        </indexterm>
9604        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
9605       </entry>
9606       <entry>
9607        <type>smallint</type>, <type>int</type>,
9608        <type>bigint</type>, <type>real</type>, <type>double
9609        precision</type>, <type>numeric</type>, or <type>interval</type>
9610       </entry>
9611       <entry>
9612        <type>numeric</type> for any integer-type argument,
9613        <type>double precision</type> for a floating-point argument,
9614        otherwise the same as the argument data type
9615       </entry>
9616       <entry>the average (arithmetic mean) of all input values</entry>
9617      </row>
9618
9619      <row>
9620       <entry>
9621        <indexterm>
9622         <primary>bit_and</primary>
9623        </indexterm>
9624        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
9625       </entry>
9626       <entry>
9627        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9628        <type>bit</type>
9629       </entry>
9630       <entry>
9631         same as argument data type
9632       </entry>
9633       <entry>the bitwise AND of all non-null input values, or null if none</entry>
9634      </row>
9635
9636      <row>
9637       <entry>
9638        <indexterm>
9639         <primary>bit_or</primary>
9640        </indexterm>
9641        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
9642       </entry>
9643       <entry>
9644        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9645        <type>bit</type>
9646       </entry>
9647       <entry>
9648         same as argument data type
9649       </entry>
9650       <entry>the bitwise OR of all non-null input values, or null if none</entry>
9651      </row>
9652
9653      <row>
9654       <entry>
9655        <indexterm>
9656         <primary>bool_and</primary>
9657        </indexterm>
9658        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
9659       </entry>
9660       <entry>
9661        <type>bool</type>
9662       </entry>
9663       <entry>
9664        <type>bool</type>
9665       </entry>
9666       <entry>true if all input values are true, otherwise false</entry>
9667      </row>
9668
9669      <row>
9670       <entry>
9671        <indexterm>
9672         <primary>bool_or</primary>
9673        </indexterm>
9674        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
9675       </entry>
9676       <entry>
9677        <type>bool</type>
9678       </entry>
9679       <entry>
9680        <type>bool</type>
9681       </entry>
9682       <entry>true if at least one input value is true, otherwise false</entry>
9683      </row>
9684
9685      <row>
9686       <entry><function>count(*)</function></entry>
9687       <entry></entry>
9688       <entry><type>bigint</type></entry>
9689       <entry>number of input rows</entry>
9690      </row>
9691
9692      <row>
9693       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
9694       <entry>any</entry>
9695       <entry><type>bigint</type></entry>
9696       <entry>
9697        number of input rows for which the value of <replaceable
9698        class="parameter">expression</replaceable> is not null
9699       </entry>
9700      </row>
9701
9702      <row>
9703       <entry>
9704        <indexterm>
9705         <primary>every</primary>
9706        </indexterm>
9707        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
9708       </entry>
9709       <entry>
9710        <type>bool</type>
9711       </entry>
9712       <entry>
9713        <type>bool</type>
9714       </entry>
9715       <entry>equivalent to <function>bool_and</function></entry>
9716      </row>
9717
9718      <row>
9719       <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
9720       <entry>any array, numeric, string, or date/time type</entry>
9721       <entry>same as argument type</entry>
9722       <entry>
9723        maximum value of <replaceable
9724        class="parameter">expression</replaceable> across all input
9725        values
9726       </entry>
9727      </row>
9728
9729      <row>
9730       <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
9731       <entry>any array, numeric, string, or date/time type</entry>
9732       <entry>same as argument type</entry>
9733       <entry>
9734        minimum value of <replaceable
9735        class="parameter">expression</replaceable> across all input
9736        values
9737       </entry>
9738      </row>
9739
9740      <row>
9741       <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></entry>
9742       <entry>
9743        <type>smallint</type>, <type>int</type>,
9744        <type>bigint</type>, <type>real</type>, <type>double
9745        precision</type>, <type>numeric</type>, or
9746        <type>interval</type>
9747       </entry>
9748       <entry>
9749        <type>bigint</type> for <type>smallint</type> or
9750        <type>int</type> arguments, <type>numeric</type> for
9751        <type>bigint</type> arguments, <type>double precision</type>
9752        for floating-point arguments, otherwise the same as the
9753        argument data type
9754       </entry>
9755       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
9756      </row>
9757
9758      <row>
9759       <entry>
9760        <indexterm>
9761         <primary>xmlagg</primary>
9762        </indexterm>
9763        <function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
9764       </entry>
9765       <entry>
9766        <type>xml</type>
9767       </entry>
9768       <entry>
9769        <type>xml</type>
9770       </entry>
9771       <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
9772      </row>
9773     </tbody>
9774    </tgroup>
9775   </table>
9776
9777   <para>
9778    It should be noted that except for <function>count</function>,
9779    these functions return a null value when no rows are selected.  In
9780    particular, <function>sum</function> of no rows returns null, not
9781    zero as one might expect, and <function>array_agg</function>
9782    returns null rather than an empty array when there are no input
9783    rows.  The <function>coalesce</function> function can be used to
9784    substitute zero or an empty array for null when necessary.
9785   </para>
9786
9787   <note>
9788     <indexterm>
9789       <primary>ANY</primary>
9790     </indexterm>
9791     <indexterm>
9792       <primary>SOME</primary>
9793     </indexterm>
9794     <para>
9795       Boolean aggregates <function>bool_and</function> and 
9796       <function>bool_or</function> correspond to standard SQL aggregates
9797       <function>every</function> and <function>any</function> or
9798       <function>some</function>. 
9799       As for <function>any</function> and <function>some</function>, 
9800       it seems that there is an ambiguity built into the standard syntax:
9801 <programlisting>
9802 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
9803 </programlisting>
9804       Here <function>ANY</function> can be considered as leading either
9805       to a subquery or to an aggregate, if the select expression returns one row.
9806       Thus the standard name cannot be given to these aggregates.
9807     </para>
9808   </note>
9809
9810   <note>
9811    <para>
9812     Users accustomed to working with other SQL database management
9813     systems might be disappointed by the performance of the
9814     <function>count</function> aggregate when it is applied to the
9815     entire table. A query like:
9816 <programlisting>
9817 SELECT count(*) FROM sometable;
9818 </programlisting>
9819     will be executed by <productname>PostgreSQL</productname> using a
9820     sequential scan of an entire table.
9821    </para>
9822   </note>
9823
9824   <para>
9825    The aggregate functions <function>array_agg</function>
9826    and <function>xmlagg</function>, as well as similar user-defined
9827    aggregate functions, produce meaningfully different result values
9828    depending on the order of the input values.  In the current
9829    implementation, the order of the input is in principle unspecified.
9830    Supplying the input values from a sorted subquery
9831    will usually work, however.  For example:
9832
9833 <screen><![CDATA[
9834 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
9835 ]]></screen>
9836
9837    But this syntax is not allowed in the SQL standard, and is
9838    not portable to other database systems.  A future version of
9839    <productname>PostgreSQL</> might provide an additional feature to control
9840    the order in a better-defined way (<literal>xmlagg(expr ORDER BY expr, expr,
9841    ...)</literal>).
9842   </para>
9843
9844   <para>
9845    <xref linkend="functions-aggregate-statistics-table"> shows
9846    aggregate functions typically used in statistical analysis.
9847    (These are separated out merely to avoid cluttering the listing
9848    of more-commonly-used aggregates.)  Where the description mentions
9849    <replaceable class="parameter">N</replaceable>, it means the
9850    number of input rows for which all the input expressions are non-null.
9851    In all cases, null is returned if the computation is meaningless,
9852    for example when <replaceable class="parameter">N</replaceable> is zero.
9853   </para>
9854
9855   <indexterm>
9856    <primary>statistics</primary>
9857   </indexterm>
9858   <indexterm>
9859    <primary>linear regression</primary>
9860   </indexterm>
9861
9862   <table id="functions-aggregate-statistics-table">
9863    <title>Aggregate Functions for Statistics</title>
9864
9865    <tgroup cols="4">
9866     <thead>
9867      <row>
9868       <entry>Function</entry>
9869       <entry>Argument Type</entry>
9870       <entry>Return Type</entry>
9871       <entry>Description</entry>
9872      </row>
9873     </thead>
9874
9875     <tbody>
9876
9877      <row>
9878       <entry>
9879        <indexterm>
9880         <primary>correlation</primary>
9881        </indexterm>
9882        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9883       </entry>
9884       <entry>
9885        <type>double precision</type>
9886       </entry>
9887       <entry>
9888        <type>double precision</type>
9889       </entry>
9890       <entry>correlation coefficient</entry>
9891      </row>
9892
9893      <row>
9894       <entry>
9895        <indexterm>
9896         <primary>covariance</primary>
9897         <secondary>population</secondary>
9898        </indexterm>
9899        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9900       </entry>
9901       <entry>
9902        <type>double precision</type>
9903       </entry>
9904       <entry>
9905        <type>double precision</type>
9906       </entry>
9907       <entry>population covariance</entry>
9908      </row>
9909
9910      <row>
9911       <entry>
9912        <indexterm>
9913         <primary>covariance</primary>
9914         <secondary>sample</secondary>
9915        </indexterm>
9916        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9917       </entry>
9918       <entry>
9919        <type>double precision</type>
9920       </entry>
9921       <entry>
9922        <type>double precision</type>
9923       </entry>
9924       <entry>sample covariance</entry>
9925      </row>
9926
9927      <row>
9928       <entry>
9929        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9930       </entry>
9931       <entry>
9932        <type>double precision</type>
9933       </entry>
9934       <entry>
9935        <type>double precision</type>
9936       </entry>
9937       <entry>average of the independent variable
9938       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9939      </row>
9940
9941      <row>
9942       <entry>
9943        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9944       </entry>
9945       <entry>
9946        <type>double precision</type>
9947       </entry>
9948       <entry>
9949        <type>double precision</type>
9950       </entry>
9951       <entry>average of the dependent variable
9952       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9953      </row>
9954
9955      <row>
9956       <entry>
9957        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9958       </entry>
9959       <entry>
9960        <type>double precision</type>
9961       </entry>
9962       <entry>
9963        <type>bigint</type>
9964       </entry>
9965       <entry>number of input rows in which both expressions are nonnull</entry>
9966      </row>
9967
9968      <row>
9969       <entry>
9970        <indexterm>
9971         <primary>regression intercept</primary>
9972        </indexterm>
9973        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9974       </entry>
9975       <entry>
9976        <type>double precision</type>
9977       </entry>
9978       <entry>
9979        <type>double precision</type>
9980       </entry>
9981       <entry>y-intercept of the least-squares-fit linear equation
9982       determined by the (<replaceable
9983       class="parameter">X</replaceable>, <replaceable
9984       class="parameter">Y</replaceable>) pairs</entry>
9985      </row>
9986
9987      <row>
9988       <entry>
9989        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9990       </entry>
9991       <entry>
9992        <type>double precision</type>
9993       </entry>
9994       <entry>
9995        <type>double precision</type>
9996       </entry>
9997       <entry>square of the correlation coefficient</entry>
9998      </row>
9999
10000      <row>
10001       <entry>
10002        <indexterm>
10003         <primary>regression slope</primary>
10004        </indexterm>
10005        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10006       </entry>
10007       <entry>
10008        <type>double precision</type>
10009       </entry>
10010       <entry>
10011        <type>double precision</type>
10012       </entry>
10013       <entry>slope of the least-squares-fit linear equation determined
10014       by the (<replaceable class="parameter">X</replaceable>,
10015       <replaceable class="parameter">Y</replaceable>) pairs</entry>
10016      </row>
10017
10018      <row>
10019       <entry>
10020        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10021       </entry>
10022       <entry>
10023        <type>double precision</type>
10024       </entry>
10025       <entry>
10026        <type>double precision</type>
10027       </entry>
10028       <entry><literal>sum(<replaceable
10029       class="parameter">X</replaceable>^2) - sum(<replaceable
10030       class="parameter">X</replaceable>)^2/<replaceable
10031       class="parameter">N</replaceable></literal> (<quote>sum of
10032       squares</quote> of the independent variable)</entry>
10033      </row>
10034
10035      <row>
10036       <entry>
10037        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10038       </entry>
10039       <entry>
10040        <type>double precision</type>
10041       </entry>
10042       <entry>
10043        <type>double precision</type>
10044       </entry>
10045       <entry><literal>sum(<replaceable
10046       class="parameter">X</replaceable>*<replaceable
10047       class="parameter">Y</replaceable>) - sum(<replaceable
10048       class="parameter">X</replaceable>) * sum(<replaceable
10049       class="parameter">Y</replaceable>)/<replaceable
10050       class="parameter">N</replaceable></literal> (<quote>sum of
10051       products</quote> of independent times dependent
10052       variable)</entry>
10053      </row>
10054
10055      <row>
10056       <entry>
10057        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10058       </entry>
10059       <entry>
10060        <type>double precision</type>
10061       </entry>
10062       <entry>
10063        <type>double precision</type>
10064       </entry>
10065       <entry><literal>sum(<replaceable
10066       class="parameter">Y</replaceable>^2) - sum(<replaceable
10067       class="parameter">Y</replaceable>)^2/<replaceable
10068       class="parameter">N</replaceable></literal> (<quote>sum of
10069       squares</quote> of the dependent variable)</entry>
10070      </row>
10071
10072      <row>
10073       <entry>
10074        <indexterm>
10075         <primary>standard deviation</primary>
10076        </indexterm>
10077        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
10078       </entry>
10079       <entry>
10080        <type>smallint</type>, <type>int</type>,
10081        <type>bigint</type>, <type>real</type>, <type>double
10082        precision</type>, or <type>numeric</type>
10083       </entry>
10084       <entry>
10085        <type>double precision</type> for floating-point arguments,
10086        otherwise <type>numeric</type>
10087       </entry>
10088       <entry>historical alias for <function>stddev_samp</function></entry>
10089      </row>
10090
10091      <row>
10092       <entry>
10093        <indexterm>
10094         <primary>standard deviation</primary>
10095         <secondary>population</secondary>
10096        </indexterm>
10097        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
10098       </entry>
10099       <entry>
10100        <type>smallint</type>, <type>int</type>,
10101        <type>bigint</type>, <type>real</type>, <type>double
10102        precision</type>, or <type>numeric</type>
10103       </entry>
10104       <entry>
10105        <type>double precision</type> for floating-point arguments,
10106        otherwise <type>numeric</type>
10107       </entry>
10108       <entry>population standard deviation of the input values</entry>
10109      </row>
10110
10111      <row>
10112       <entry>
10113        <indexterm>
10114         <primary>standard deviation</primary>
10115         <secondary>sample</secondary>
10116        </indexterm>
10117        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
10118       </entry>
10119       <entry>
10120        <type>smallint</type>, <type>int</type>,
10121        <type>bigint</type>, <type>real</type>, <type>double
10122        precision</type>, or <type>numeric</type>
10123       </entry>
10124       <entry>
10125        <type>double precision</type> for floating-point arguments,
10126        otherwise <type>numeric</type>
10127       </entry>
10128       <entry>sample standard deviation of the input values</entry>
10129      </row>
10130
10131      <row>
10132       <entry>
10133        <indexterm>
10134         <primary>variance</primary>
10135        </indexterm>
10136        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
10137       </entry>
10138       <entry>
10139        <type>smallint</type>, <type>int</type>,
10140        <type>bigint</type>, <type>real</type>, <type>double
10141        precision</type>, or <type>numeric</type>
10142       </entry>
10143       <entry>
10144        <type>double precision</type> for floating-point arguments,
10145        otherwise <type>numeric</type>
10146       </entry>
10147       <entry>historical alias for <function>var_samp</function></entry>
10148      </row>
10149
10150      <row>
10151       <entry>
10152        <indexterm>
10153         <primary>variance</primary>
10154         <secondary>population</secondary>
10155        </indexterm>
10156        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
10157       </entry>
10158       <entry>
10159        <type>smallint</type>, <type>int</type>,
10160        <type>bigint</type>, <type>real</type>, <type>double
10161        precision</type>, or <type>numeric</type>
10162       </entry>
10163       <entry>
10164        <type>double precision</type> for floating-point arguments,
10165        otherwise <type>numeric</type>
10166       </entry>
10167       <entry>population variance of the input values (square of the population standard deviation)</entry>
10168      </row>
10169
10170      <row>
10171       <entry>
10172        <indexterm>
10173         <primary>variance</primary>
10174         <secondary>sample</secondary>
10175        </indexterm>
10176        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
10177       </entry>
10178       <entry>
10179        <type>smallint</type>, <type>int</type>,
10180        <type>bigint</type>, <type>real</type>, <type>double
10181        precision</type>, or <type>numeric</type>
10182       </entry>
10183       <entry>
10184        <type>double precision</type> for floating-point arguments,
10185        otherwise <type>numeric</type>
10186       </entry>
10187       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
10188      </row>
10189     </tbody>
10190    </tgroup>
10191   </table>
10192
10193  </sect1>
10194
10195  <sect1 id="functions-window">
10196   <title>Window Functions</title>
10197
10198   <indexterm zone="functions-window">
10199    <primary>window function</primary>
10200    <secondary>built-in</secondary>
10201   </indexterm>
10202
10203   <para>
10204    <firstterm>Window functions</firstterm> provide the ability to perform
10205    calculations across sets of rows that are related to the current query
10206    row.  See <xref linkend="tutorial-window"> for an introduction to this
10207    feature.
10208   </para>
10209
10210   <para>
10211    The built-in window functions are listed in
10212    <xref linkend="functions-window-table">.  Note that these functions
10213    <emphasis>must</> be invoked using window function syntax; that is an
10214    <literal>OVER</> clause is required.
10215   </para>
10216
10217   <para>
10218    In addition to these functions, any built-in or user-defined aggregate
10219    function can be used as a window function (see
10220    <xref linkend="functions-aggregate"> for a list of the built-in aggregates).
10221    Aggregate functions act as window functions only when an <literal>OVER</>
10222    clause follows the call; otherwise they act as regular aggregates.
10223   </para>
10224
10225   <table id="functions-window-table">
10226    <title>General-Purpose Window Functions</title>
10227
10228    <tgroup cols="3">
10229     <thead>
10230      <row>
10231       <entry>Function</entry>
10232       <entry>Return Type</entry>
10233       <entry>Description</entry>
10234      </row>
10235     </thead>
10236
10237     <tbody>
10238      <row>
10239       <entry>
10240        <indexterm>
10241         <primary>row_number</primary>
10242        </indexterm>
10243        <function>row_number()</function>
10244       </entry>
10245       <entry>
10246        <type>bigint</type>
10247       </entry>
10248       <entry>number of the current row within its partition, counting from 1</entry>
10249      </row>
10250
10251      <row>
10252       <entry>
10253        <indexterm>
10254         <primary>rank</primary>
10255        </indexterm>
10256        <function>rank()</function>
10257       </entry>
10258       <entry>
10259        <type>bigint</type>
10260       </entry>
10261       <entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
10262      </row>
10263
10264      <row>
10265       <entry>
10266        <indexterm>
10267         <primary>dense_rank</primary>
10268        </indexterm>
10269        <function>dense_rank()</function>
10270       </entry>
10271       <entry>
10272        <type>bigint</type>
10273       </entry>
10274       <entry>rank of the current row without gaps; this function counts peer groups</entry>
10275      </row>
10276
10277      <row>
10278       <entry>
10279        <indexterm>
10280         <primary>percent_rank</primary>
10281        </indexterm>
10282        <function>percent_rank()</function>
10283       </entry>
10284       <entry>
10285        <type>double precision</type>
10286       </entry>
10287       <entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
10288      </row>
10289
10290      <row>
10291       <entry>
10292        <indexterm>
10293         <primary>cume_dist</primary>
10294        </indexterm>
10295        <function>cume_dist()</function>
10296       </entry>
10297       <entry>
10298        <type>double precision</type>
10299       </entry>
10300       <entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
10301      </row>
10302
10303      <row>
10304       <entry>
10305        <indexterm>
10306         <primary>ntile</primary>
10307        </indexterm>
10308        <function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</>)</function>
10309       </entry>
10310       <entry>
10311        <type>integer</type>
10312       </entry>
10313       <entry>integer ranging from 1 to the argument value, dividing the
10314        partition as equally as possible</entry>
10315      </row>
10316
10317      <row>
10318       <entry>
10319        <indexterm>
10320         <primary>lag</primary>
10321        </indexterm>
10322        <function>
10323          lag(<replaceable class="parameter">value</replaceable> <type>any</>
10324              [, <replaceable class="parameter">offset</replaceable> <type>integer</>
10325              [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
10326        </function>
10327       </entry>
10328       <entry>
10329        <type>same type as <replaceable class="parameter">value</replaceable></type>
10330       </entry>
10331       <entry>
10332        returns <replaceable class="parameter">value</replaceable> evaluated at
10333        the row that is <replaceable class="parameter">offset</replaceable>
10334        rows before the current row within the partition; if there is no such
10335        row, instead return <replaceable class="parameter">default</replaceable>.
10336        Both <replaceable class="parameter">offset</replaceable> and
10337        <replaceable class="parameter">default</replaceable> are evaluated
10338        with respect to the current row.  If omitted,
10339        <replaceable class="parameter">offset</replaceable> defaults to 1 and
10340        <replaceable class="parameter">default</replaceable> to null
10341       </entry>
10342      </row>
10343
10344      <row>
10345       <entry>
10346        <indexterm>
10347         <primary>lead</primary>
10348        </indexterm>
10349        <function>
10350          lead(<replaceable class="parameter">value</replaceable> <type>any</>
10351               [, <replaceable class="parameter">offset</replaceable> <type>integer</>
10352               [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
10353        </function>
10354       </entry>
10355       <entry>
10356        <type>same type as <replaceable class="parameter">value</replaceable></type>
10357       </entry>
10358       <entry>
10359        returns <replaceable class="parameter">value</replaceable> evaluated at
10360        the row that is <replaceable class="parameter">offset</replaceable>
10361        rows after the current row within the partition; if there is no such
10362        row, instead return <replaceable class="parameter">default</replaceable>.
10363        Both <replaceable class="parameter">offset</replaceable> and
10364        <replaceable class="parameter">default</replaceable> are evaluated
10365        with respect to the current row.  If omitted,
10366        <replaceable class="parameter">offset</replaceable> defaults to 1 and
10367        <replaceable class="parameter">default</replaceable> to null
10368       </entry>
10369      </row>
10370
10371      <row>
10372       <entry>
10373        <indexterm>
10374         <primary>first_value</primary>
10375        </indexterm>
10376        <function>first_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
10377       </entry>
10378       <entry>
10379        <type>same type as <replaceable class="parameter">value</replaceable></type>
10380       </entry>
10381       <entry>
10382        returns <replaceable class="parameter">value</replaceable> evaluated
10383        at the row that is the first row of the window frame
10384       </entry>
10385      </row>
10386
10387      <row>
10388       <entry>
10389        <indexterm>
10390         <primary>last_value</primary>
10391        </indexterm>
10392        <function>last_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
10393       </entry>
10394       <entry>
10395        <type>same type as <replaceable class="parameter">value</replaceable></type>
10396       </entry>
10397       <entry>
10398        returns <replaceable class="parameter">value</replaceable> evaluated
10399        at the row that is the last row of the window frame
10400       </entry>
10401      </row>
10402
10403      <row>
10404       <entry>
10405        <indexterm>
10406         <primary>nth_value</primary>
10407        </indexterm>
10408        <function>
10409          nth_value(<replaceable class="parameter">value</replaceable> <type>any</>, <replaceable class="parameter">nth</replaceable> <type>integer</>)
10410        </function>
10411       </entry>
10412       <entry>
10413        <type>same type as <replaceable class="parameter">value</replaceable></type>
10414       </entry>
10415       <entry>
10416        returns <replaceable class="parameter">value</replaceable> evaluated
10417        at the row that is the <replaceable class="parameter">nth</replaceable>
10418        row of the window frame (counting from 1); null if no such row
10419       </entry>
10420      </row>
10421     </tbody>
10422    </tgroup>
10423   </table>
10424
10425   <para>
10426    All of the functions listed in
10427    <xref linkend="functions-window-table"> depend on the sort ordering
10428    specified by the <literal>ORDER BY</> clause of the associated window
10429    definition.  Rows that are not distinct in the <literal>ORDER BY</>
10430    ordering are said to be <firstterm>peers</>; the four ranking functions
10431    are defined so that they give the same answer for any two peer rows.
10432   </para>
10433
10434   <para>
10435    Note that <function>first_value</>, <function>last_value</>, and
10436    <function>nth_value</> consider only the rows within the <quote>window
10437    frame</>, which by default contains the rows from the start of the
10438    partition through the last peer of the current row.  This is
10439    likely to give unhelpful results for <function>nth_value</> and
10440    particularly <function>last_value</>.  You can redefine the frame as
10441    being the whole partition by adding <literal>ROWS BETWEEN UNBOUNDED
10442    PRECEDING AND UNBOUNDED FOLLOWING</> to the <literal>OVER</> clause.
10443    See <xref linkend="syntax-window-functions"> for more information.
10444   </para>
10445
10446   <para>
10447    When an aggregate function is used as a window function, it aggregates
10448    over the rows within the current row's window frame.  To obtain
10449    aggregation over the whole partition, omit <literal>ORDER BY</> or use
10450    <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
10451    An aggregate used with <literal>ORDER BY</> and the default window frame
10452    definition produces a <quote>running sum</> type of behavior, which may or
10453    may not be what's wanted.
10454   </para>
10455
10456   <note>
10457    <para>
10458     The SQL standard defines a <literal>RESPECT NULLS</> or
10459     <literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
10460     <function>first_value</>, <function>last_value</>, and
10461     <function>nth_value</>.  This is not implemented in
10462     <productname>PostgreSQL</productname>: the behavior is always the
10463     same as the standard's default, namely <literal>RESPECT NULLS</>.
10464     Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
10465     option for <function>nth_value</> is not implemented: only the
10466     default <literal>FROM FIRST</> behavior is supported.  (You can achieve
10467     the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
10468     ordering.)
10469    </para>
10470   </note>
10471
10472  </sect1>
10473
10474  <sect1 id="functions-subquery">
10475   <title>Subquery Expressions</title>
10476
10477   <indexterm>
10478    <primary>EXISTS</primary>
10479   </indexterm>
10480
10481   <indexterm>
10482    <primary>IN</primary>
10483   </indexterm>
10484
10485   <indexterm>
10486    <primary>NOT IN</primary>
10487   </indexterm>
10488
10489   <indexterm>
10490    <primary>ANY</primary>
10491   </indexterm>
10492
10493   <indexterm>
10494    <primary>ALL</primary>
10495   </indexterm>
10496
10497   <indexterm>
10498    <primary>SOME</primary>
10499   </indexterm>
10500
10501   <indexterm>
10502    <primary>subquery</primary>
10503   </indexterm>
10504
10505   <para>
10506    This section describes the <acronym>SQL</acronym>-compliant subquery
10507    expressions available in <productname>PostgreSQL</productname>.
10508    All of the expression forms documented in this section return
10509    Boolean (true/false) results.
10510   </para>
10511
10512   <sect2>
10513    <title><literal>EXISTS</literal></title>
10514
10515 <synopsis>
10516 EXISTS (<replaceable>subquery</replaceable>)
10517 </synopsis>
10518
10519   <para>
10520    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
10521    or <firstterm>subquery</firstterm>.  The
10522    subquery is evaluated to determine whether it returns any rows.
10523    If it returns at least one row, the result of <token>EXISTS</token> is
10524    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token> 
10525    is <quote>false</>.
10526   </para>
10527
10528   <para>
10529    The subquery can refer to variables from the surrounding query,
10530    which will act as constants during any one evaluation of the subquery.
10531   </para>
10532
10533   <para>
10534    The subquery will generally only be executed long enough to determine
10535    whether at least one row is returned, not all the way to completion.
10536    It is unwise to write a subquery that has side effects (such as
10537    calling sequence functions); whether the side effects occur
10538    might be unpredictable.
10539   </para>
10540
10541   <para>
10542    Since the result depends only on whether any rows are returned,
10543    and not on the contents of those rows, the output list of the
10544    subquery is normally unimportant.  A common coding convention is
10545    to write all <literal>EXISTS</> tests in the form
10546    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
10547    this rule however, such as subqueries that use <token>INTERSECT</token>.
10548   </para>
10549
10550   <para>
10551    This simple example is like an inner join on <literal>col2</>, but
10552    it produces at most one output row for each <literal>tab1</> row,
10553    even if there are several matching <literal>tab2</> rows:
10554 <screen>
10555 SELECT col1
10556 FROM tab1
10557 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
10558 </screen>
10559   </para>
10560   </sect2>
10561
10562   <sect2>
10563    <title><literal>IN</literal></title>
10564
10565 <synopsis>
10566 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
10567 </synopsis>
10568
10569   <para>
10570    The right-hand side is a parenthesized
10571    subquery, which must return exactly one column.  The left-hand expression
10572    is evaluated and compared to each row of the subquery result.
10573    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10574    The result is <quote>false</> if no equal row is found (including the
10575    case where the subquery returns no rows).
10576   </para>
10577
10578   <para>
10579    Note that if the left-hand expression yields null, or if there are
10580    no equal right-hand values and at least one right-hand row yields
10581    null, the result of the <token>IN</token> construct will be null, not false.
10582    This is in accordance with SQL's normal rules for Boolean combinations
10583    of null values.
10584   </para>
10585
10586   <para>
10587    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10588    be evaluated completely.
10589   </para>
10590
10591 <synopsis>
10592 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
10593 </synopsis>
10594
10595   <para>
10596    The left-hand side of this form of <token>IN</token> is a row constructor,
10597    as described in <xref linkend="sql-syntax-row-constructors">.
10598    The right-hand side is a parenthesized
10599    subquery, which must return exactly as many columns as there are
10600    expressions in the left-hand row.  The left-hand expressions are
10601    evaluated and compared row-wise to each row of the subquery result.
10602    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10603    The result is <quote>false</> if no equal row is found (including the
10604    case where the subquery returns no rows).
10605   </para>
10606
10607   <para>
10608    As usual, null values in the rows are combined per
10609    the normal rules of SQL Boolean expressions.  Two rows are considered
10610    equal if all their corresponding members are non-null and equal; the rows
10611    are unequal if any corresponding members are non-null and unequal;
10612    otherwise the result of that row comparison is unknown (null).
10613    If all the per-row results are either unequal or null, with at least one
10614    null, then the result of <token>IN</token> is null.
10615   </para>
10616   </sect2>
10617
10618   <sect2>
10619    <title><literal>NOT IN</literal></title>
10620
10621 <synopsis>
10622 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10623 </synopsis>
10624
10625   <para>
10626    The right-hand side is a parenthesized
10627    subquery, which must return exactly one column.  The left-hand expression
10628    is evaluated and compared to each row of the subquery result.
10629    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10630    are found (including the case where the subquery returns no rows).
10631    The result is <quote>false</> if any equal row is found.
10632   </para>
10633
10634   <para>
10635    Note that if the left-hand expression yields null, or if there are
10636    no equal right-hand values and at least one right-hand row yields
10637    null, the result of the <token>NOT IN</token> construct will be null, not true.
10638    This is in accordance with SQL's normal rules for Boolean combinations
10639    of null values.
10640   </para>
10641
10642   <para>
10643    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10644    be evaluated completely.
10645   </para>
10646
10647 <synopsis>
10648 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10649 </synopsis>
10650
10651   <para>
10652    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
10653    as described in <xref linkend="sql-syntax-row-constructors">.
10654    The right-hand side is a parenthesized
10655    subquery, which must return exactly as many columns as there are
10656    expressions in the left-hand row.  The left-hand expressions are
10657    evaluated and compared row-wise to each row of the subquery result.
10658    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10659    are found (including the case where the subquery returns no rows).
10660    The result is <quote>false</> if any equal row is found.
10661   </para>
10662
10663   <para>
10664    As usual, null values in the rows are combined per
10665    the normal rules of SQL Boolean expressions.  Two rows are considered
10666    equal if all their corresponding members are non-null and equal; the rows
10667    are unequal if any corresponding members are non-null and unequal;
10668    otherwise the result of that row comparison is unknown (null).
10669    If all the per-row results are either unequal or null, with at least one
10670    null, then the result of <token>NOT IN</token> is null.
10671   </para>
10672   </sect2>
10673
10674   <sect2>
10675    <title><literal>ANY</literal>/<literal>SOME</literal></title>
10676
10677 <synopsis>
10678 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
10679 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
10680 </synopsis>
10681
10682   <para>
10683    The right-hand side is a parenthesized
10684    subquery, which must return exactly one column.  The left-hand expression
10685    is evaluated and compared to each row of the subquery result using the
10686    given <replaceable>operator</replaceable>, which must yield a Boolean
10687    result.
10688    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10689    The result is <quote>false</> if no true result is found (including the
10690    case where the subquery returns no rows).
10691   </para>
10692
10693   <para>
10694    <token>SOME</token> is a synonym for <token>ANY</token>.
10695    <token>IN</token> is equivalent to <literal>= ANY</literal>.
10696   </para>
10697
10698   <para>
10699    Note that if there are no successes and at least one right-hand row yields
10700    null for the operator's result, the result of the <token>ANY</token> construct
10701    will be null, not false.
10702    This is in accordance with SQL's normal rules for Boolean combinations
10703    of null values.
10704   </para>
10705
10706   <para>
10707    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10708    be evaluated completely.
10709   </para>
10710
10711 <synopsis>
10712 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
10713 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
10714 </synopsis>
10715
10716   <para>
10717    The left-hand side of this form of <token>ANY</token> is a row constructor,
10718    as described in <xref linkend="sql-syntax-row-constructors">.
10719    The right-hand side is a parenthesized
10720    subquery, which must return exactly as many columns as there are
10721    expressions in the left-hand row.  The left-hand expressions are
10722    evaluated and compared row-wise to each row of the subquery result,
10723    using the given <replaceable>operator</replaceable>.
10724    The result of <token>ANY</token> is <quote>true</> if the comparison
10725    returns true for any subquery row.
10726    The result is <quote>false</> if the comparison returns false for every
10727    subquery row (including the case where the subquery returns no
10728    rows).
10729    The result is NULL if the comparison does not return true for any row,
10730    and it returns NULL for at least one row.
10731   </para>
10732
10733   <para>
10734    See <xref linkend="row-wise-comparison"> for details about the meaning
10735    of a row-wise comparison.
10736   </para>
10737   </sect2>
10738
10739   <sect2>
10740    <title><literal>ALL</literal></title>
10741
10742 <synopsis>
10743 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10744 </synopsis>
10745
10746   <para>
10747    The right-hand side is a parenthesized
10748    subquery, which must return exactly one column.  The left-hand expression
10749    is evaluated and compared to each row of the subquery result using the
10750    given <replaceable>operator</replaceable>, which must yield a Boolean
10751    result.
10752    The result of <token>ALL</token> is <quote>true</> if all rows yield true
10753    (including the case where the subquery returns no rows).
10754    The result is <quote>false</> if any false result is found.
10755    The result is NULL if the comparison does not return false for any row,
10756    and it returns NULL for at least one row.
10757   </para>
10758
10759   <para>
10760    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
10761   </para>
10762
10763   <para>
10764    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10765    be evaluated completely.
10766   </para>
10767
10768 <synopsis>
10769 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10770 </synopsis>
10771
10772   <para>
10773    The left-hand side of this form of <token>ALL</token> is a row constructor,
10774    as described in <xref linkend="sql-syntax-row-constructors">.
10775    The right-hand side is a parenthesized
10776    subquery, which must return exactly as many columns as there are
10777    expressions in the left-hand row.  The left-hand expressions are
10778    evaluated and compared row-wise to each row of the subquery result,
10779    using the given <replaceable>operator</replaceable>.
10780    The result of <token>ALL</token> is <quote>true</> if the comparison
10781    returns true for all subquery rows (including the
10782    case where the subquery returns no rows).
10783    The result is <quote>false</> if the comparison returns false for any
10784    subquery row.
10785    The result is NULL if the comparison does not return false for any
10786    subquery row, and it returns NULL for at least one row.
10787   </para>
10788
10789   <para>
10790    See <xref linkend="row-wise-comparison"> for details about the meaning
10791    of a row-wise comparison.
10792   </para>
10793   </sect2>
10794
10795   <sect2>
10796    <title>Row-wise Comparison</title>
10797
10798    <indexterm zone="functions-subquery">
10799     <primary>comparison</primary>
10800     <secondary>subquery result row</secondary>
10801    </indexterm>
10802
10803 <synopsis>
10804 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
10805 </synopsis>
10806
10807   <para>
10808    The left-hand side is a row constructor,
10809    as described in <xref linkend="sql-syntax-row-constructors">.
10810    The right-hand side is a parenthesized subquery, which must return exactly
10811    as many columns as there are expressions in the left-hand row. Furthermore,
10812    the subquery cannot return more than one row.  (If it returns zero rows,
10813    the result is taken to be null.)  The left-hand side is evaluated and
10814    compared row-wise to the single subquery result row.
10815   </para>
10816
10817   <para>
10818    See <xref linkend="row-wise-comparison"> for details about the meaning
10819    of a row-wise comparison.
10820   </para>
10821   </sect2>
10822  </sect1>
10823
10824
10825  <sect1 id="functions-comparisons">
10826   <title>Row and Array Comparisons</title>
10827
10828   <indexterm>
10829    <primary>IN</primary>
10830   </indexterm>
10831
10832   <indexterm>
10833    <primary>NOT IN</primary>
10834   </indexterm>
10835
10836   <indexterm>
10837    <primary>ANY</primary>
10838   </indexterm>
10839
10840   <indexterm>
10841    <primary>ALL</primary>
10842   </indexterm>
10843
10844   <indexterm>
10845    <primary>SOME</primary>
10846   </indexterm>
10847
10848   <indexterm>
10849    <primary>row-wise comparison</primary>
10850   </indexterm>
10851
10852   <indexterm>
10853    <primary>comparison</primary>
10854    <secondary>row-wise</secondary>
10855   </indexterm>
10856
10857   <indexterm>
10858    <primary>IS DISTINCT FROM</primary>
10859   </indexterm>
10860
10861   <indexterm>
10862    <primary>IS NOT DISTINCT FROM</primary>
10863   </indexterm>
10864
10865   <para>
10866    This section describes several specialized constructs for making
10867    multiple comparisons between groups of values.  These forms are
10868    syntactically related to the subquery forms of the previous section,
10869    but do not involve subqueries.
10870    The forms involving array subexpressions are
10871    <productname>PostgreSQL</productname> extensions; the rest are
10872    <acronym>SQL</acronym>-compliant.
10873    All of the expressions documented in this section return
10874    Boolean (true/false) results.
10875   </para>
10876
10877   <sect2>
10878    <title><literal>IN</literal></title>
10879
10880 <synopsis>
10881 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10882 </synopsis>
10883
10884   <para>
10885    The right-hand side is a parenthesized list
10886    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
10887    result is equal to any of the right-hand expressions.  This is a shorthand
10888    notation for
10889
10890 <synopsis>
10891 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
10892 OR
10893 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
10894 OR
10895 ...
10896 </synopsis>
10897   </para>
10898
10899   <para>
10900    Note that if the left-hand expression yields null, or if there are
10901    no equal right-hand values and at least one right-hand expression yields
10902    null, the result of the <token>IN</token> construct will be null, not false.
10903    This is in accordance with SQL's normal rules for Boolean combinations
10904    of null values.
10905   </para>
10906   </sect2>
10907
10908   <sect2>
10909    <title><literal>NOT IN</literal></title>
10910
10911 <synopsis>
10912 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10913 </synopsis>
10914
10915   <para>
10916    The right-hand side is a parenthesized list
10917    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
10918    result is unequal to all of the right-hand expressions.  This is a shorthand
10919    notation for
10920
10921 <synopsis>
10922 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
10923 AND
10924 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
10925 AND
10926 ...
10927 </synopsis>
10928   </para>
10929
10930   <para>
10931    Note that if the left-hand expression yields null, or if there are
10932    no equal right-hand values and at least one right-hand expression yields
10933    null, the result of the <token>NOT IN</token> construct will be null, not true
10934    as one might naively expect.
10935    This is in accordance with SQL's normal rules for Boolean combinations
10936    of null values.
10937   </para>
10938
10939   <tip>
10940   <para>
10941    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
10942    cases.  However, null values are much more likely to trip up the novice when
10943    working with <token>NOT IN</token> than when working with <token>IN</token>.
10944    It is best to express your condition positively if possible.
10945   </para>
10946   </tip>
10947   </sect2>
10948
10949   <sect2>
10950    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
10951
10952 <synopsis>
10953 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
10954 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
10955 </synopsis>
10956
10957   <para>
10958    The right-hand side is a parenthesized expression, which must yield an
10959    array value.
10960    The left-hand expression
10961    is evaluated and compared to each element of the array using the
10962    given <replaceable>operator</replaceable>, which must yield a Boolean
10963    result.
10964    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10965    The result is <quote>false</> if no true result is found (including the
10966    case where the array has zero elements).
10967   </para>
10968
10969   <para>
10970    If the array expression yields a null array, the result of
10971    <token>ANY</token> will be null.  If the left-hand expression yields null,
10972    the result of <token>ANY</token> is ordinarily null (though a non-strict
10973    comparison operator could possibly yield a different result).
10974    Also, if the right-hand array contains any null elements and no true
10975    comparison result is obtained, the result of <token>ANY</token>
10976    will be null, not false (again, assuming a strict comparison operator).
10977    This is in accordance with SQL's normal rules for Boolean combinations
10978    of null values.
10979   </para>
10980
10981   <para>
10982    <token>SOME</token> is a synonym for <token>ANY</token>.
10983   </para>
10984   </sect2>
10985
10986   <sect2>
10987    <title><literal>ALL</literal> (array)</title>
10988
10989 <synopsis>
10990 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
10991 </synopsis>
10992
10993   <para>
10994    The right-hand side is a parenthesized expression, which must yield an
10995    array value.
10996    The left-hand expression
10997    is evaluated and compared to each element of the array using the
10998    given <replaceable>operator</replaceable>, which must yield a Boolean
10999    result.
11000    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
11001    (including the case where the array has zero elements).
11002    The result is <quote>false</> if any false result is found.
11003   </para>
11004
11005   <para>
11006    If the array expression yields a null array, the result of
11007    <token>ALL</token> will be null.  If the left-hand expression yields null,
11008    the result of <token>ALL</token> is ordinarily null (though a non-strict
11009    comparison operator could possibly yield a different result).
11010    Also, if the right-hand array contains any null elements and no false
11011    comparison result is obtained, the result of <token>ALL</token>
11012    will be null, not true (again, assuming a strict comparison operator).
11013    This is in accordance with SQL's normal rules for Boolean combinations
11014    of null values.
11015   </para>
11016   </sect2>
11017
11018   <sect2 id="row-wise-comparison">
11019    <title>Row-wise Comparison</title>
11020
11021 <synopsis>
11022 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
11023 </synopsis>
11024
11025   <para>
11026    Each side is a row constructor,
11027    as described in <xref linkend="sql-syntax-row-constructors">.
11028    The two row values must have the same number of fields.
11029    Each side is evaluated and they are compared row-wise.  Row comparisons
11030    are allowed when the <replaceable>operator</replaceable> is
11031    <literal>=</>,
11032    <literal>&lt;&gt;</>,
11033    <literal>&lt;</>,
11034    <literal>&lt;=</>,
11035    <literal>&gt;</> or
11036    <literal>&gt;=</>,
11037    or has semantics similar to one of these.  (To be specific, an operator
11038    can be a row comparison operator if it is a member of a B-Tree operator
11039    class, or is the negator of the <literal>=</> member of a B-Tree operator
11040    class.)
11041   </para>
11042
11043   <para>
11044    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
11045    from the others.  Two rows are considered
11046    equal if all their corresponding members are non-null and equal; the rows
11047    are unequal if any corresponding members are non-null and unequal;
11048    otherwise the result of the row comparison is unknown (null).
11049   </para>
11050
11051   <para>
11052    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
11053    <literal>&gt;=</> cases, the row elements are compared left-to-right,
11054    stopping as soon as an unequal or null pair of elements is found.
11055    If either of this pair of elements is null, the result of the
11056    row comparison is unknown (null); otherwise comparison of this pair
11057    of elements determines the result.  For example,
11058    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
11059    yields true, not null, because the third pair of elements are not
11060    considered.
11061   </para>
11062
11063   <note>
11064    <para>
11065     Prior to <productname>PostgreSQL</productname> 8.2, the
11066     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
11067     cases were not handled per SQL specification.  A comparison like
11068     <literal>ROW(a,b) &lt; ROW(c,d)</>
11069     was implemented as
11070     <literal>a &lt; c AND b &lt; d</>
11071     whereas the correct behavior is equivalent to
11072     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
11073    </para>
11074   </note>
11075
11076 <synopsis>
11077 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
11078 </synopsis>
11079
11080   <para>
11081    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
11082    but it does not yield null for null inputs.  Instead, any null value is
11083    considered unequal to (distinct from) any non-null value, and any two
11084    nulls are considered equal (not distinct).  Thus the result will
11085    either be true or false, never null.
11086   </para>
11087
11088 <synopsis>
11089 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
11090 </synopsis>
11091
11092   <para>
11093    This construct is similar to a <literal>=</literal> row comparison,
11094    but it does not yield null for null inputs.  Instead, any null value is
11095    considered unequal to (distinct from) any non-null value, and any two
11096    nulls are considered equal (not distinct).  Thus the result will always
11097    be either true or false, never null.
11098   </para>
11099
11100   <note>
11101    <para>
11102     The SQL specification requires row-wise comparison to return NULL if the
11103     result depends on comparing two NULL values or a NULL and a non-NULL.
11104     <productname>PostgreSQL</productname> does this only when comparing the
11105     results of two row constructors or comparing a row constructor to the
11106     output of a subquery (as in <xref linkend="functions-subquery">).
11107     In other contexts where two composite-type values are compared, two
11108     NULL field values are considered equal, and a NULL is considered larger
11109     than a non-NULL.  This is necessary in order to have consistent sorting
11110     and indexing behavior for composite types.
11111    </para>
11112   </note>
11113
11114   </sect2>
11115  </sect1>
11116
11117  <sect1 id="functions-srf">
11118   <title>Set Returning Functions</title>
11119
11120   <indexterm zone="functions-srf">
11121    <primary>set returning functions</primary>
11122    <secondary>functions</secondary>
11123   </indexterm>
11124
11125   <indexterm>
11126    <primary>generate_series</primary>
11127   </indexterm>
11128
11129   <para>
11130    This section describes functions that possibly return more than one row.
11131    Currently the only functions in this class are series generating functions,
11132    as detailed in <xref linkend="functions-srf-series"> and
11133    <xref linkend="functions-srf-subscripts">.
11134   </para>
11135
11136   <table id="functions-srf-series">
11137    <title>Series Generating Functions</title>
11138    <tgroup cols="4">
11139     <thead>
11140      <row>
11141       <entry>Function</entry>
11142       <entry>Argument Type</entry>
11143       <entry>Return Type</entry>
11144       <entry>Description</entry>
11145      </row>
11146     </thead>
11147
11148     <tbody>
11149      <row>
11150       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>)</literal></entry>
11151       <entry><type>int</type> or <type>bigint</type></entry>
11152       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
11153       <entry>
11154        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11155        with a step size of one
11156       </entry>
11157      </row>
11158
11159      <row>
11160       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</literal></entry>
11161       <entry><type>int</type> or <type>bigint</type></entry>
11162       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
11163       <entry>
11164        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11165        with a step size of <parameter>step</parameter>
11166       </entry>
11167      </row>
11168
11169      <row>
11170       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</literal></entry>
11171       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
11172       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
11173       <entry>
11174        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11175        with a step size of <parameter>step</parameter>
11176       </entry>
11177      </row>
11178
11179     </tbody>
11180    </tgroup>
11181   </table>
11182
11183   <para>
11184    When <parameter>step</parameter> is positive, zero rows are returned if
11185    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
11186    Conversely, when <parameter>step</parameter> is negative, zero rows are
11187    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
11188    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
11189    for <parameter>step</parameter> to be zero. Some examples follow:
11190 <programlisting>
11191 SELECT * FROM generate_series(2,4);
11192  generate_series
11193 -----------------
11194                2
11195                3
11196                4
11197 (3 rows)
11198
11199 SELECT * FROM generate_series(5,1,-2);
11200  generate_series
11201 -----------------
11202                5
11203                3
11204                1
11205 (3 rows)
11206
11207 SELECT * FROM generate_series(4,3);
11208  generate_series
11209 -----------------
11210 (0 rows)
11211
11212 -- this example relies on the date-plus-integer operator
11213 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
11214    dates
11215 ------------
11216  2004-02-05
11217  2004-02-12
11218  2004-02-19
11219 (3 rows)
11220
11221 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
11222                               '2008-03-04 12:00', '10 hours');
11223    generate_series   
11224 ---------------------
11225  2008-03-01 00:00:00
11226  2008-03-01 10:00:00
11227  2008-03-01 20:00:00
11228  2008-03-02 06:00:00
11229  2008-03-02 16:00:00
11230  2008-03-03 02:00:00
11231  2008-03-03 12:00:00
11232  2008-03-03 22:00:00
11233  2008-03-04 08:00:00
11234 (9 rows)
11235 </programlisting>
11236   </para>
11237
11238   <table id="functions-srf-subscripts">
11239    <title>Subscript Generating Functions</title>
11240    <tgroup cols="3">
11241     <thead>
11242      <row>
11243       <entry>Function</entry>
11244       <entry>Return Type</entry>
11245       <entry>Description</entry>
11246      </row>
11247     </thead>
11248
11249     <tbody>
11250      <row>
11251       <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</literal></entry>
11252       <entry><type>setof int</type></entry>
11253       <entry>
11254        Generate a series comprising the given array's subscripts.
11255       </entry>
11256      </row>
11257
11258      <row>
11259       <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</literal></entry>
11260       <entry><type>setof int</type></entry>
11261       <entry>
11262        Generate a series comprising the given array's subscripts. When
11263        <parameter>reverse</parameter> is true, the series is returned in
11264        reverse order.
11265       </entry>
11266      </row>
11267
11268     </tbody>
11269    </tgroup>
11270   </table>
11271
11272   <indexterm>
11273    <primary>generate_subscripts</primary>
11274   </indexterm>
11275
11276   <para>
11277    <function>generate_subscripts</> is a convenience function that generates
11278    the set of valid subscripts for the specified dimension of the given
11279    array.
11280    Zero rows are returned for arrays that do not have the requested dimension,
11281    or for NULL arrays (but valid subscripts are returned for NULL array
11282    elements).  Some examples follow:
11283 <programlisting>
11284 -- basic usage
11285 select generate_subscripts('{NULL,1,NULL,2}'::int[], 1) as s;
11286  s 
11287 ---
11288  1
11289  2
11290  3
11291  4
11292 (4 rows)
11293
11294 -- presenting an array, the subscript and the subscripted
11295 -- value requires a subquery
11296 select * from arrays;
11297          a          
11298 --------------------
11299  {-1,-2}
11300  {100,200}
11301 (2 rows)
11302
11303 select a as array, s as subscript, a[s] as value
11304 from (select generate_subscripts(a, 1) as s, a from arrays) foo;
11305    array   | subscript | value 
11306 -----------+-----------+-------
11307  {-1,-2}   |         1 |    -1
11308  {-1,-2}   |         2 |    -2
11309  {100,200} |         1 |   100
11310  {100,200} |         2 |   200
11311 (4 rows)
11312
11313 -- unnest a 2D array
11314 create or replace function unnest2(anyarray)
11315 returns setof anyelement as $$
11316 select $1[i][j] 
11317    from generate_subscripts($1,1) g1(i),
11318         generate_subscripts($1,2) g2(j);
11319 $$ language sql immutable;
11320 CREATE FUNCTION
11321 postgres=# select * from unnest2(array[[1,2],[3,4]]);
11322  unnest2 
11323 ---------
11324        1
11325        2
11326        3
11327        4
11328 (4 rows)
11329 </programlisting>
11330   </para>
11331
11332  </sect1>
11333
11334  <sect1 id="functions-info">
11335   <title>System Information Functions</title>
11336
11337   <para>
11338    <xref linkend="functions-info-session-table"> shows several
11339    functions that extract session and system information.
11340   </para>
11341
11342   <para>
11343    In addition to the functions listed in this section, there are a number of
11344    functions related to the statistics system that also provide system
11345    information. See <xref linkend="monitoring-stats-views"> for more
11346    information.
11347   </para>
11348
11349    <table id="functions-info-session-table">
11350     <title>Session Information Functions</title>
11351     <tgroup cols="3">
11352      <thead>
11353       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11354      </thead>
11355
11356      <tbody>
11357       <row>
11358        <entry><literal><function>current_catalog</function></literal></entry>
11359        <entry><type>name</type></entry>
11360        <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
11361       </row>
11362
11363       <row>
11364        <entry><literal><function>current_database</function>()</literal></entry>
11365        <entry><type>name</type></entry>
11366        <entry>name of current database</entry>
11367       </row>
11368
11369       <row>
11370        <entry><literal><function>current_schema</function>[()]</literal></entry>
11371        <entry><type>name</type></entry>
11372        <entry>name of current schema</entry>
11373       </row>
11374
11375       <row>
11376        <entry><literal><function>current_schemas</function>(<type>boolean</type>)</literal></entry>
11377        <entry><type>name[]</type></entry>
11378        <entry>names of schemas in search path optionally including implicit schemas</entry>
11379       </row>
11380
11381       <row>
11382        <entry><literal><function>current_user</function></literal></entry>
11383        <entry><type>name</type></entry>
11384        <entry>user name of current execution context</entry>
11385       </row>
11386
11387       <row>
11388        <entry><literal><function>current_query</function></literal></entry>
11389        <entry><type>text</type></entry>
11390        <entry>text of the currently executing query, as submitted
11391        by the client (might contain more than one statement)</entry>
11392       </row>  
11393
11394       <row>
11395        <!-- See also the entry for this in monitoring.sgml -->
11396        <entry><literal><function>pg_backend_pid</function>()</literal></entry>
11397        <entry><type>int</type></entry>
11398        <entry>
11399         Process ID of the server process attached to the current session
11400        </entry>
11401       </row>
11402
11403       <row>
11404        <entry><literal><function>inet_client_addr</function>()</literal></entry>
11405        <entry><type>inet</type></entry>
11406        <entry>address of the remote connection</entry>
11407       </row>
11408
11409       <row>
11410        <entry><literal><function>inet_client_port</function>()</literal></entry>
11411        <entry><type>int</type></entry>
11412        <entry>port of the remote connection</entry>
11413       </row>
11414
11415       <row>
11416        <entry><literal><function>inet_server_addr</function>()</literal></entry>
11417        <entry><type>inet</type></entry>
11418        <entry>address of the local connection</entry>
11419       </row>
11420
11421       <row>
11422        <entry><literal><function>inet_server_port</function>()</literal></entry>
11423        <entry><type>int</type></entry>
11424        <entry>port of the local connection</entry>
11425       </row>
11426
11427       <row>
11428        <entry><literal><function>pg_my_temp_schema</function>()</literal></entry>
11429        <entry><type>oid</type></entry>
11430        <entry>OID of session's temporary schema, or 0 if none</entry>
11431       </row>
11432
11433       <row>
11434        <entry><literal><function>pg_is_other_temp_schema</function>(<type>oid</type>)</literal></entry>
11435        <entry><type>boolean</type></entry>
11436        <entry>is schema another session's temporary schema?</entry>
11437       </row>
11438
11439       <row>
11440        <entry><literal><function>pg_postmaster_start_time</function>()</literal></entry>
11441        <entry><type>timestamp with time zone</type></entry>
11442        <entry>server start time</entry>
11443       </row>
11444
11445       <row>
11446        <entry><literal><function>pg_conf_load_time</function>()</literal></entry>
11447        <entry><type>timestamp with time zone</type></entry>
11448        <entry>configuration load time</entry>
11449       </row>
11450
11451       <row>
11452        <entry><literal><function>session_user</function></literal></entry>
11453        <entry><type>name</type></entry>
11454        <entry>session user name</entry>
11455       </row>
11456
11457       <row>
11458        <entry><literal><function>user</function></literal></entry>
11459        <entry><type>name</type></entry>
11460        <entry>equivalent to <function>current_user</function></entry>
11461       </row>
11462
11463       <row>
11464        <entry><literal><function>version</function>()</literal></entry>
11465        <entry><type>text</type></entry>
11466        <entry><productname>PostgreSQL</> version information</entry>
11467       </row>
11468      </tbody>
11469     </tgroup>
11470    </table>
11471
11472    <indexterm>
11473     <primary>user</primary>
11474     <secondary>current</secondary>
11475    </indexterm>
11476
11477    <indexterm>
11478     <primary>schema</primary>
11479     <secondary>current</secondary>
11480    </indexterm>
11481
11482    <indexterm>
11483     <primary>search path</primary>
11484     <secondary>current</secondary>
11485    </indexterm>
11486
11487    <indexterm>
11488     <primary>current_catalog</primary>
11489    </indexterm>
11490
11491    <indexterm>
11492     <primary>current_database</primary>
11493    </indexterm>
11494
11495    <indexterm>
11496     <primary>current_schema</primary>
11497    </indexterm>
11498
11499    <indexterm>
11500     <primary>current_user</primary>
11501    </indexterm>
11502
11503    <para>
11504     The <function>session_user</function> is normally the user who initiated
11505     the current database connection; but superusers can change this setting
11506     with <xref linkend="sql-set-session-authorization" endterm="sql-set-session-authorization-title">.
11507     The <function>current_user</function> is the user identifier
11508     that is applicable for permission checking. Normally it is equal
11509     to the session user, but it can be changed with
11510     <xref linkend="sql-set-role" endterm="sql-set-role-title">.
11511     It also changes during the execution of
11512     functions with the attribute <literal>SECURITY DEFINER</literal>.
11513     In Unix parlance, the session user is the <quote>real user</quote> and
11514     the current user is the <quote>effective user</quote>.
11515    </para>
11516
11517    <note>
11518     <para>
11519      <function>current_catalog</function>, <function>current_schema</function>,
11520      <function>current_user</function>, <function>session_user</function>,
11521      and <function>user</function> have special syntactic status
11522      in <acronym>SQL</acronym>: they must be called without trailing
11523      parentheses (optional in PostgreSQL in the case
11524      of <function>current_schema</function>).
11525     </para>
11526    </note>
11527
11528    <para>
11529     <function>current_schema</function> returns the name of the schema that is
11530     first in the search path (or a null value if the search path is
11531     empty).  This is the schema that will be used for any tables or
11532     other named objects that are created without specifying a target schema.
11533     <function>current_schemas(boolean)</function> returns an array of the names of all
11534     schemas presently in the search path.  The Boolean option determines whether or not
11535     implicitly included system schemas such as <literal>pg_catalog</> are included in the
11536     returned search path.
11537    </para>
11538
11539    <note>
11540     <para>
11541      The search path can be altered at run time.  The command is:
11542 <programlisting>
11543 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
11544 </programlisting>
11545     </para>
11546    </note>
11547
11548    <indexterm>
11549     <primary>inet_client_addr</primary>
11550    </indexterm>
11551
11552    <indexterm>
11553     <primary>inet_client_port</primary>
11554    </indexterm>
11555
11556    <indexterm>
11557     <primary>inet_server_addr</primary>
11558    </indexterm>
11559
11560    <indexterm>
11561     <primary>inet_server_port</primary>
11562    </indexterm>
11563
11564    <para>
11565      <function>inet_client_addr</function> returns the IP address of the
11566      current client, and <function>inet_client_port</function> returns the
11567      port number.
11568      <function>inet_server_addr</function> returns the IP address on which
11569      the server accepted the current connection, and
11570      <function>inet_server_port</function> returns the port number.
11571      All these functions return NULL if the current connection is via a
11572      Unix-domain socket.
11573    </para>
11574
11575    <indexterm>
11576     <primary>pg_my_temp_schema</primary>
11577    </indexterm>
11578
11579    <indexterm>
11580     <primary>pg_is_other_temp_schema</primary>
11581    </indexterm>
11582
11583    <para>
11584     <function>pg_my_temp_schema</function> returns the OID of the current
11585     session's temporary schema, or 0 if it has none (because no
11586     temporary tables have been created).
11587     <function>pg_is_other_temp_schema</function> returns true if the
11588     given OID is the OID of another session's temporary schema.
11589     (This can be useful, for example, to exclude other sessions' temporary
11590     tables from a catalog display.)
11591    </para>
11592
11593    <indexterm>
11594     <primary>pg_postmaster_start_time</primary>
11595    </indexterm>
11596
11597    <para>
11598     <function>pg_postmaster_start_time</function> returns the
11599     <type>timestamp with time zone</type> when the
11600     server started.
11601    </para>
11602
11603    <indexterm>
11604     <primary>pg_conf_load_time</primary>
11605    </indexterm>
11606
11607    <para>
11608     <function>pg_conf_load_time</function> returns the
11609     <type>timestamp with time zone</type> when the
11610     server configuration files were last loaded.
11611     (If the current session was alive at the time, this will be the time
11612     when the session itself re-read the configuration files, so the
11613     reading will vary a little in different sessions.  Otherwise it is
11614     the time when the postmaster process re-read the configuration files.)
11615    </para>
11616
11617    <indexterm>
11618     <primary>version</primary>
11619    </indexterm>
11620
11621    <para>
11622     <function>version</function> returns a string describing the
11623     <productname>PostgreSQL</productname> server's version.
11624    </para>
11625
11626   <indexterm>
11627    <primary>privilege</primary>
11628    <secondary>querying</secondary>
11629   </indexterm>
11630
11631   <para>
11632    <xref linkend="functions-info-access-table"> lists functions that
11633    allow the user to query object access privileges programmatically.
11634    See <xref linkend="ddl-priv"> for more information about
11635    privileges.
11636   </para>
11637
11638    <table id="functions-info-access-table">
11639     <title>Access Privilege Inquiry Functions</title>
11640     <tgroup cols="3">
11641      <thead>
11642       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11643      </thead>
11644
11645      <tbody>
11646       <row>
11647        <entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
11648                                   <parameter>table</parameter>,
11649                                   <parameter>privilege</parameter>)</literal>
11650        </entry>
11651        <entry><type>boolean</type></entry>
11652        <entry>does user have privilege for any column of table</entry>
11653       </row>
11654       <row>
11655        <entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
11656                                   <parameter>privilege</parameter>)</literal>
11657        </entry>
11658        <entry><type>boolean</type></entry>
11659        <entry>does current user have privilege for any column of table</entry>
11660       </row>
11661       <row>
11662        <entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
11663                                   <parameter>table</parameter>,
11664                                   <parameter>column</parameter>,
11665                                   <parameter>privilege</parameter>)</literal>
11666        </entry>
11667        <entry><type>boolean</type></entry>
11668        <entry>does user have privilege for column</entry>
11669       </row>
11670       <row>
11671        <entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
11672                                   <parameter>column</parameter>,
11673                                   <parameter>privilege</parameter>)</literal>
11674        </entry>
11675        <entry><type>boolean</type></entry>
11676        <entry>does current user have privilege for column</entry>
11677       </row>
11678       <row>
11679        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
11680                                   <parameter>database</parameter>,
11681                                   <parameter>privilege</parameter>)</literal>
11682        </entry>
11683        <entry><type>boolean</type></entry>
11684        <entry>does user have privilege for database</entry>
11685       </row>
11686       <row>
11687        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
11688                                   <parameter>privilege</parameter>)</literal>
11689        </entry>
11690        <entry><type>boolean</type></entry>
11691        <entry>does current user have privilege for database</entry>
11692       </row>
11693       <row>
11694        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
11695                                   <parameter>fdw</parameter>,
11696                                   <parameter>privilege</parameter>)</literal>
11697        </entry>
11698        <entry><type>boolean</type></entry>
11699        <entry>does user have privilege for foreign-data wrapper</entry>
11700       </row>
11701       <row>
11702        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
11703                                   <parameter>privilege</parameter>)</literal>
11704        </entry>
11705        <entry><type>boolean</type></entry>
11706        <entry>does current user have privilege for foreign-data wrapper</entry>
11707       </row>
11708       <row>
11709        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
11710                                   <parameter>function</parameter>,
11711                                   <parameter>privilege</parameter>)</literal>
11712        </entry>
11713        <entry><type>boolean</type></entry>
11714        <entry>does user have privilege for function</entry>
11715       </row>
11716       <row>
11717        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
11718                                   <parameter>privilege</parameter>)</literal>
11719        </entry>
11720        <entry><type>boolean</type></entry>
11721        <entry>does current user have privilege for function</entry>
11722       </row>
11723       <row>
11724        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
11725                                   <parameter>language</parameter>,
11726                                   <parameter>privilege</parameter>)</literal>
11727        </entry>
11728        <entry><type>boolean</type></entry>
11729        <entry>does user have privilege for language</entry>
11730       </row>
11731       <row>
11732        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
11733                                   <parameter>privilege</parameter>)</literal>
11734        </entry>
11735        <entry><type>boolean</type></entry>
11736        <entry>does current user have privilege for language</entry>
11737       </row>
11738       <row>
11739        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
11740                                   <parameter>schema</parameter>,
11741                                   <parameter>privilege</parameter>)</literal>
11742        </entry>
11743        <entry><type>boolean</type></entry>
11744        <entry>does user have privilege for schema</entry>
11745       </row>
11746       <row>
11747        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
11748                                   <parameter>privilege</parameter>)</literal>
11749        </entry>
11750        <entry><type>boolean</type></entry>
11751        <entry>does current user have privilege for schema</entry>
11752       </row>
11753       <row>
11754        <entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
11755                                   <parameter>server</parameter>,
11756                                   <parameter>privilege</parameter>)</literal>
11757        </entry>
11758        <entry><type>boolean</type></entry>
11759        <entry>does user have privilege for foreign server</entry>
11760       </row>
11761       <row>
11762        <entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
11763                                   <parameter>privilege</parameter>)</literal>
11764        </entry>
11765        <entry><type>boolean</type></entry>
11766        <entry>does current user have privilege for foreign server</entry>
11767       </row>
11768       <row>
11769        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
11770                                   <parameter>table</parameter>,
11771                                   <parameter>privilege</parameter>)</literal>
11772        </entry>
11773        <entry><type>boolean</type></entry>
11774        <entry>does user have privilege for table</entry>
11775       </row>
11776       <row>
11777        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
11778                                   <parameter>privilege</parameter>)</literal>
11779        </entry>
11780        <entry><type>boolean</type></entry>
11781        <entry>does current user have privilege for table</entry>
11782       </row>
11783       <row>
11784        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
11785                                   <parameter>tablespace</parameter>,
11786                                   <parameter>privilege</parameter>)</literal>
11787        </entry>
11788        <entry><type>boolean</type></entry>
11789        <entry>does user have privilege for tablespace</entry>
11790       </row>
11791       <row>
11792        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
11793                                   <parameter>privilege</parameter>)</literal>
11794        </entry>
11795        <entry><type>boolean</type></entry>
11796        <entry>does current user have privilege for tablespace</entry>
11797       </row>
11798       <row>
11799        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
11800                                   <parameter>role</parameter>,
11801                                   <parameter>privilege</parameter>)</literal>
11802        </entry>
11803        <entry><type>boolean</type></entry>
11804        <entry>does user have privilege for role</entry>
11805       </row>
11806       <row>
11807        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
11808                                   <parameter>privilege</parameter>)</literal>
11809        </entry>
11810        <entry><type>boolean</type></entry>
11811        <entry>does current user have privilege for role</entry>
11812       </row>
11813      </tbody>
11814     </tgroup>
11815    </table>
11816
11817    <indexterm>
11818     <primary>has_any_column_privilege</primary>
11819    </indexterm>
11820    <indexterm>
11821     <primary>has_column_privilege</primary>
11822    </indexterm>
11823    <indexterm>
11824     <primary>has_database_privilege</primary>
11825    </indexterm>
11826    <indexterm>
11827     <primary>has_function_privilege</primary>
11828    </indexterm>
11829    <indexterm>
11830     <primary>has_foreign_data_wrapper_privilege</primary>
11831    </indexterm>
11832    <indexterm>
11833     <primary>has_language_privilege</primary>
11834    </indexterm>
11835    <indexterm>
11836     <primary>has_schema_privilege</primary>
11837    </indexterm>
11838    <indexterm>
11839     <primary>has_server_privilege</primary>
11840    </indexterm>
11841    <indexterm>
11842     <primary>has_table_privilege</primary>
11843    </indexterm>
11844    <indexterm>
11845     <primary>has_tablespace_privilege</primary>
11846    </indexterm>
11847    <indexterm>
11848     <primary>pg_has_role</primary>
11849    </indexterm>
11850
11851    <para>
11852     <function>has_table_privilege</function> checks whether a user
11853     can access a table in a particular way.  The user can be
11854     specified by name or by OID
11855     (<literal>pg_authid.oid</literal>), or if the argument is
11856     omitted
11857     <function>current_user</function> is assumed.  The table can be specified
11858     by name or by OID.  (Thus, there are actually six variants of
11859     <function>has_table_privilege</function>, which can be distinguished by
11860     the number and types of their arguments.)  When specifying by name,
11861     the name can be schema-qualified if necessary.
11862     The desired access privilege type
11863     is specified by a text string, which must evaluate to one of the
11864     values <literal>SELECT</literal>, <literal>INSERT</literal>,
11865     <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
11866     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.  Optionally,
11867     <literal>WITH GRANT OPTION</> can be added to a privilege type to test
11868     whether the privilege is held with grant option.  Also, multiple privilege
11869     types can be listed separated by commas, in which case the result will
11870     be <literal>true</> if any of the listed privileges is held.
11871     (Case of the privilege string is not significant, and extra whitespace
11872     is allowed between but not within privilege names.)
11873     Some examples:
11874 <programlisting>
11875 SELECT has_table_privilege('myschema.mytable', 'select');
11876 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
11877 </programlisting>
11878    </para>
11879
11880    <para>
11881     <function>has_any_column_privilege</function> checks whether a user can
11882     access any column of a table in a particular way; its argument possibilities
11883     are analogous to <function>has_table_privilege</>,
11884     except that the desired access privilege type must evaluate to some
11885     combination of
11886     <literal>SELECT</literal>,
11887     <literal>INSERT</literal>,
11888     <literal>UPDATE</literal>, or
11889     <literal>REFERENCES</literal>.  Note that having any of these privileges
11890     at the table level implicitly grants it for each column of the table,
11891     so <function>has_any_column_privilege</function> will always return
11892     <literal>true</> if <function>has_table_privilege</> does for the same
11893     arguments.  But <function>has_any_column_privilege</> also succeeds if
11894     there is a column-level grant of the privilege for at least one column.
11895    </para>
11896
11897    <para>
11898     <function>has_column_privilege</function> checks whether a user
11899     can access a column in a particular way;  its argument possibilities
11900     are analogous to <function>has_table_privilege</function>,
11901     with the addition that the column can be specified either by name
11902     or attribute number.
11903     The desired access privilege type must evaluate to some combination of
11904     <literal>SELECT</literal>,
11905     <literal>INSERT</literal>,
11906     <literal>UPDATE</literal>, or
11907     <literal>REFERENCES</literal>.  Note that having any of these privileges
11908     at the table level implicitly grants it for each column of the table.
11909    </para>
11910
11911    <para>
11912     <function>has_database_privilege</function> checks whether a user
11913     can access a database in a particular way; its argument possibilities
11914     are analogous to <function>has_table_privilege</function>.
11915     The desired access privilege type must evaluate to some combination of
11916     <literal>CREATE</literal>,
11917     <literal>CONNECT</literal>,
11918     <literal>TEMPORARY</literal>, or
11919     <literal>TEMP</literal> (which is equivalent to
11920     <literal>TEMPORARY</literal>).
11921    </para>
11922
11923    <para>
11924     <function>has_function_privilege</function> checks whether a user
11925     can access a function in a particular way; its argument  possibilities
11926     are analogous to <function>has_table_privilege</function>.
11927     When specifying a function by a text string rather than by OID,
11928     the allowed input is the same as for the <type>regprocedure</> data type
11929     (see <xref linkend="datatype-oid">).
11930     The desired access privilege type must evaluate to
11931     <literal>EXECUTE</literal>.
11932     An example is:
11933 <programlisting>
11934 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
11935 </programlisting>
11936    </para>
11937
11938    <para>
11939     <function>has_foreign_data_wrapper_privilege</function> checks whether a user
11940     can access a foreign-data wrapper in a particular way; its argument possibilities
11941     are analogous to <function>has_table_privilege</function>.
11942     The desired access privilege type must evaluate to
11943     <literal>USAGE</literal>.
11944    </para>
11945
11946    <para>
11947     <function>has_language_privilege</function> checks whether a user
11948     can access a procedural language in a particular way;  its argument possibilities
11949     are analogous to <function>has_table_privilege</function>.
11950     The desired access privilege type must evaluate to
11951     <literal>USAGE</literal>.
11952    </para>
11953
11954    <para>
11955     <function>has_schema_privilege</function> checks whether a user
11956     can access a schema in a particular way; its argument possibilities
11957     are analogous to <function>has_table_privilege</function>.
11958     The desired access privilege type must evaluate to some combination of
11959     <literal>CREATE</literal> or
11960     <literal>USAGE</literal>.
11961    </para>
11962
11963    <para>
11964     <function>has_server_privilege</function> checks whether a user
11965     can access a foreign server in a particular way;  its argument possibilities
11966     are analogous to <function>has_table_privilege</function>.
11967     The desired access privilege type must evaluate to
11968     <literal>USAGE</literal>.
11969    </para>
11970
11971    <para>
11972     <function>has_tablespace_privilege</function> checks whether a user
11973     can access a tablespace in a particular way;  its argument possibilities
11974     are analogous to <function>has_table_privilege</function>.
11975     The desired access privilege type must evaluate to
11976     <literal>CREATE</literal>.
11977    </para>
11978
11979    <para>
11980     <function>pg_has_role</function> checks whether a user
11981     can access a role in a particular way; its argument possibilities
11982     are analogous to <function>has_table_privilege</function>.
11983     The desired access privilege type must evaluate to some combination of
11984     <literal>MEMBER</literal> or
11985     <literal>USAGE</literal>.
11986     <literal>MEMBER</literal> denotes direct or indirect membership in
11987     the role (that is, the right to do <command>SET ROLE</>), while
11988     <literal>USAGE</literal> denotes whether the privileges of the role
11989     are immediately available without doing <command>SET ROLE</>.
11990    </para>
11991
11992   <para>
11993    <xref linkend="functions-info-schema-table"> shows functions that
11994    determine whether a certain object is <firstterm>visible</> in the
11995    current schema search path.
11996    For example, a table is said to be visible if its
11997    containing schema is in the search path and no table of the same
11998    name appears earlier in the search path.  This is equivalent to the
11999    statement that the table can be referenced by name without explicit
12000    schema qualification.  To list the names of all visible tables:
12001 <programlisting>
12002 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
12003 </programlisting>
12004   </para>
12005
12006    <table id="functions-info-schema-table">
12007     <title>Schema Visibility Inquiry Functions</title>
12008     <tgroup cols="3">
12009      <thead>
12010       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12011      </thead>
12012
12013      <tbody>
12014       <row>
12015        <entry><literal><function>pg_conversion_is_visible</function>(<parameter>conversion_oid</parameter>)</literal>
12016        </entry>
12017        <entry><type>boolean</type></entry>
12018        <entry>is conversion visible in search path</entry>
12019       </row>
12020       <row>
12021        <entry><literal><function>pg_function_is_visible</function>(<parameter>function_oid</parameter>)</literal>
12022        </entry>
12023        <entry><type>boolean</type></entry>
12024        <entry>is function visible in search path</entry>
12025       </row>
12026       <row>
12027        <entry><literal><function>pg_operator_is_visible</function>(<parameter>operator_oid</parameter>)</literal>
12028        </entry>
12029        <entry><type>boolean</type></entry>
12030        <entry>is operator visible in search path</entry>
12031       </row>
12032       <row>
12033        <entry><literal><function>pg_opclass_is_visible</function>(<parameter>opclass_oid</parameter>)</literal>
12034        </entry>
12035        <entry><type>boolean</type></entry>
12036        <entry>is operator class visible in search path</entry>
12037       </row>
12038       <row>
12039        <entry><literal><function>pg_table_is_visible</function>(<parameter>table_oid</parameter>)</literal>
12040        </entry>
12041        <entry><type>boolean</type></entry>
12042        <entry>is table visible in search path</entry>
12043       </row>
12044       <row>
12045        <entry><literal><function>pg_ts_config_is_visible</function>(<parameter>config_oid</parameter>)</literal>
12046        </entry>
12047        <entry><type>boolean</type></entry>
12048        <entry>is text search configuration visible in search path</entry>
12049       </row>
12050       <row>
12051        <entry><literal><function>pg_ts_dict_is_visible</function>(<parameter>dict_oid</parameter>)</literal>
12052        </entry>
12053        <entry><type>boolean</type></entry>
12054        <entry>is text search dictionary visible in search path</entry>
12055       </row>
12056       <row>
12057        <entry><literal><function>pg_ts_parser_is_visible</function>(<parameter>parser_oid</parameter>)</literal>
12058        </entry>
12059        <entry><type>boolean</type></entry>
12060        <entry>is text search parser visible in search path</entry>
12061       </row>
12062       <row>
12063        <entry><literal><function>pg_ts_template_is_visible</function>(<parameter>template_oid</parameter>)</literal>
12064        </entry>
12065        <entry><type>boolean</type></entry>
12066        <entry>is text search template visible in search path</entry>
12067       </row>
12068       <row>
12069        <entry><literal><function>pg_type_is_visible</function>(<parameter>type_oid</parameter>)</literal>
12070        </entry>
12071        <entry><type>boolean</type></entry>
12072        <entry>is type (or domain) visible in search path</entry>
12073       </row>
12074      </tbody>
12075     </tgroup>
12076    </table>
12077
12078    <indexterm>
12079     <primary>pg_conversion_is_visible</primary>
12080    </indexterm>
12081    <indexterm>
12082     <primary>pg_function_is_visible</primary>
12083    </indexterm>
12084    <indexterm>
12085     <primary>pg_operator_is_visible</primary>
12086    </indexterm>
12087    <indexterm>
12088     <primary>pg_opclass_is_visible</primary>
12089    </indexterm>
12090    <indexterm>
12091     <primary>pg_table_is_visible</primary>
12092    </indexterm>
12093    <indexterm>
12094     <primary>pg_ts_config_is_visible</primary>
12095    </indexterm>
12096    <indexterm>
12097     <primary>pg_ts_dict_is_visible</primary>
12098    </indexterm>
12099    <indexterm>
12100     <primary>pg_ts_parser_is_visible</primary>
12101    </indexterm>
12102    <indexterm>
12103     <primary>pg_ts_template_is_visible</primary>
12104    </indexterm>
12105    <indexterm>
12106     <primary>pg_type_is_visible</primary>
12107    </indexterm>
12108
12109    <para>
12110     Each function performs the visibility check for one type of database
12111     object.  Note that <function>pg_table_is_visible</function> can also be used
12112     with views, indexes and sequences; <function>pg_type_is_visible</function>
12113     can also be used with domains. For functions and operators, an object in
12114     the search path is visible if there is no object of the same name
12115     <emphasis>and argument data type(s)</> earlier in the path.  For operator
12116     classes, both name and associated index access method are considered.
12117    </para>
12118
12119    <para>
12120     All these functions require object OIDs to identify the object to be
12121     checked.  If you want to test an object by name, it is convenient to use
12122     the OID alias types (<type>regclass</>, <type>regtype</>,
12123     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
12124     or <type>regdictionary</>),
12125     for example:
12126 <programlisting>
12127 SELECT pg_type_is_visible('myschema.widget'::regtype);
12128 </programlisting>
12129     Note that it would not make much sense to test a non-schema-qualified
12130     type name in this way &mdash; if the name can be recognized at all, it must be visible.
12131    </para>
12132
12133    <indexterm>
12134     <primary>format_type</primary>
12135    </indexterm>
12136
12137    <indexterm>
12138     <primary>pg_get_keywords</primary>
12139    </indexterm>
12140
12141    <indexterm>
12142     <primary>pg_get_viewdef</primary>
12143    </indexterm>
12144
12145    <indexterm>
12146     <primary>pg_get_ruledef</primary>
12147    </indexterm>
12148
12149    <indexterm>
12150     <primary>pg_get_functiondef</primary>
12151    </indexterm>
12152
12153    <indexterm>
12154     <primary>pg_get_function_arguments</primary>
12155    </indexterm>
12156
12157    <indexterm>
12158     <primary>pg_get_function_identity_arguments</primary>
12159    </indexterm>
12160
12161    <indexterm>
12162     <primary>pg_get_function_result</primary>
12163    </indexterm>
12164
12165    <indexterm>
12166     <primary>pg_get_indexdef</primary>
12167    </indexterm>
12168
12169    <indexterm>
12170     <primary>pg_get_triggerdef</primary>
12171    </indexterm>
12172
12173    <indexterm>
12174     <primary>pg_get_constraintdef</primary>
12175    </indexterm>
12176
12177    <indexterm>
12178     <primary>pg_get_expr</primary>
12179    </indexterm>
12180
12181    <indexterm>
12182     <primary>pg_get_userbyid</primary>
12183    </indexterm>
12184
12185    <indexterm>
12186     <primary>pg_get_serial_sequence</primary>
12187    </indexterm>
12188
12189    <indexterm>
12190     <primary>pg_tablespace_databases</primary>
12191    </indexterm>
12192
12193    <indexterm>
12194     <primary>pg_typeof</primary>
12195    </indexterm>
12196
12197   <para>
12198    <xref linkend="functions-info-catalog-table"> lists functions that
12199    extract information from the system catalogs.
12200   </para>
12201
12202    <table id="functions-info-catalog-table">
12203     <title>System Catalog Information Functions</title>
12204     <tgroup cols="3">
12205      <thead>
12206       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12207      </thead>
12208
12209      <tbody>
12210       <row>
12211        <entry><literal><function>format_type</function>(<parameter>type_oid</parameter>, <parameter>typemod</>)</literal></entry>
12212        <entry><type>text</type></entry>
12213        <entry>get SQL name of a data type</entry>
12214       </row>
12215       <row>
12216        <entry><literal><function>pg_get_keywords</function>()</literal></entry>
12217        <entry><type>setof record</type></entry>
12218        <entry>get list of SQL keywords and their categories</entry>
12219       </row>
12220       <row>
12221        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>)</literal></entry>
12222        <entry><type>text</type></entry>
12223        <entry>get definition of a constraint</entry>
12224       </row>
12225       <row>
12226        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
12227        <entry><type>text</type></entry>
12228        <entry>get definition of a constraint</entry>
12229       </row>
12230       <row>
12231        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>)</literal></entry>
12232        <entry><type>text</type></entry>
12233        <entry>decompile internal form of an expression, assuming that any Vars
12234        in it refer to the relation indicated by the second parameter</entry>
12235       </row>
12236       <row>
12237        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</literal></entry>
12238        <entry><type>text</type></entry>
12239        <entry>decompile internal form of an expression, assuming that any Vars
12240        in it refer to the relation indicated by the second parameter</entry>
12241       </row>
12242       <row>
12243        <entry><literal><function>pg_get_functiondef</function>(<parameter>func_oid</parameter>)</literal></entry>
12244        <entry><type>text</type></entry>
12245        <entry>get definition of a function</entry>
12246       </row>
12247       <row>
12248        <entry><literal><function>pg_get_function_arguments</function>(<parameter>func_oid</parameter>)</literal></entry>
12249        <entry><type>text</type></entry>
12250        <entry>get argument list of function's definition (with default values)</entry>
12251       </row>
12252       <row>
12253        <entry><literal><function>pg_get_function_identity_arguments</function>(<parameter>func_oid</parameter>)</literal></entry>
12254        <entry><type>text</type></entry>
12255        <entry>get argument list to identify a function (without default values)</entry>
12256       </row>
12257       <row>
12258        <entry><literal><function>pg_get_function_result</function>(<parameter>func_oid</parameter>)</literal></entry>
12259        <entry><type>text</type></entry>
12260        <entry>get <literal>RETURNS</> clause for function</entry>
12261       </row>
12262       <row>
12263        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
12264        <entry><type>text</type></entry>
12265        <entry>get <command>CREATE INDEX</> command for index</entry>
12266       </row>
12267       <row>
12268        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</literal></entry>
12269        <entry><type>text</type></entry>
12270        <entry>get <command>CREATE INDEX</> command for index,
12271        or definition of just one index column when
12272        <parameter>column_no</> is not zero</entry>
12273       </row>
12274       <row>
12275        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>)</literal></entry>
12276        <entry><type>text</type></entry>
12277        <entry>get <command>CREATE RULE</> command for rule</entry>
12278       </row>
12279       <row>
12280        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
12281        <entry><type>text</type></entry>
12282        <entry>get <command>CREATE RULE</> command for rule</entry>
12283       </row>
12284       <row>
12285        <entry><literal><function>pg_get_serial_sequence</function>(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</literal></entry>
12286        <entry><type>text</type></entry>
12287        <entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
12288        uses</entry>
12289       </row>
12290       <row>
12291        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
12292        <entry><type>text</type></entry>
12293        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
12294       </row>
12295       <row>
12296        <entry><literal><function>pg_get_userbyid</function>(<parameter>roleid</parameter>)</literal></entry>
12297        <entry><type>name</type></entry>
12298        <entry>get role name with given OID</entry>
12299       </row>
12300       <row>
12301        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>)</literal></entry>
12302        <entry><type>text</type></entry>
12303        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
12304       </row>
12305       <row>
12306        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</literal></entry>
12307        <entry><type>text</type></entry>
12308        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
12309       </row>
12310       <row>
12311        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>)</literal></entry>
12312        <entry><type>text</type></entry>
12313        <entry>get underlying <command>SELECT</command> command for view</entry>
12314       </row>
12315       <row>
12316        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
12317        <entry><type>text</type></entry>
12318        <entry>get underlying <command>SELECT</command> command for view</entry>
12319       </row>
12320       <row>
12321        <entry><literal><function>pg_tablespace_databases</function>(<parameter>tablespace_oid</parameter>)</literal></entry>
12322        <entry><type>setof oid</type></entry>
12323        <entry>get the set of database OIDs that have objects in the tablespace</entry>
12324       </row>
12325       <row>
12326        <entry><literal><function>pg_typeof</function>(<parameter>any</parameter>)</literal></entry>
12327        <entry><type>regtype</type></entry>
12328        <entry>get the data type of any value</entry>
12329       </row>
12330      </tbody>
12331     </tgroup>
12332    </table>
12333
12334   <para>
12335    <function>format_type</function> returns the SQL name of a data type that
12336    is identified by its type OID and possibly a type modifier.  Pass NULL
12337    for the type modifier if no specific modifier is known.
12338   </para>
12339
12340   <para>
12341    <function>pg_get_keywords</function> returns a set of records describing
12342    the SQL keywords recognized by the server. The <structfield>word</> column
12343    contains the keyword.  The <structfield>catcode</> column contains a
12344    category code: <literal>U</> for unreserved, <literal>C</> for column name,
12345    <literal>T</> for type or function name, or <literal>R</> for reserved.
12346    The <structfield>catdesc</> column contains a possibly-localized string
12347    describing the category.
12348   </para>
12349
12350   <para>
12351    <function>pg_get_constraintdef</function>,
12352    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
12353    and <function>pg_get_triggerdef</function>, respectively reconstruct the
12354    creating command for a constraint, index, rule, or trigger. (Note that this
12355    is a decompiled reconstruction, not the original text of the command.)
12356    <function>pg_get_expr</function> decompiles the internal form of an
12357    individual expression, such as the default value for a column.  It can be
12358    useful when examining the contents of system catalogs.
12359    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
12360    query that defines a view. Most of these functions come in two variants,
12361    one of which can optionally <quote>pretty-print</> the result.  The
12362    pretty-printed format is more readable, but the default format is more
12363    likely to be interpreted the same way by future versions of
12364    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
12365    purposes.  Passing <literal>false</> for the pretty-print parameter yields
12366    the same result as the variant that does not have the parameter at all.
12367   </para>
12368
12369   <para>
12370    <function>pg_get_functiondef</> returns a complete
12371    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
12372    <function>pg_get_function_arguments</function> returns the argument list
12373    of a function, in the form it would need to appear in within
12374    <command>CREATE FUNCTION</>.
12375    <function>pg_get_function_result</function> similarly returns the
12376    appropriate <literal>RETURNS</> clause for the function.
12377    <function>pg_get_function_identity_arguments</function> returns the
12378    argument list necessary to identify a function, in the form it
12379    would need to appear in within <command>ALTER FUNCTION</>, for
12380    instance.  This form omits default values.
12381   </para>
12382
12383   <para>
12384    <function>pg_get_serial_sequence</function> returns the name of the
12385    sequence associated with a column, or NULL if no sequence is associated
12386    with the column.  The first input parameter is a table name with
12387    optional schema, and the second parameter is a column name.  Because
12388    the first parameter is potentially a schema and table, it is not treated
12389    as a double-quoted identifier, meaning it is lowercased by default,
12390    while the second parameter, being just a column name, is treated as
12391    double-quoted and has its case preserved.  The function returns a value
12392    suitably formatted for passing to sequence functions (see <xref
12393    linkend="functions-sequence">).  This association can be modified or
12394    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
12395    probably should have been called
12396    <function>pg_get_owned_sequence</function>; its current name reflects the fact
12397    that it's typically used with <type>serial</> or <type>bigserial</>
12398    columns.)
12399   </para>
12400
12401   <para>
12402    <function>pg_get_userbyid</function> extracts a role's name given
12403    its OID.
12404   </para>
12405
12406   <para>
12407    <function>pg_tablespace_databases</function> allows a tablespace to be
12408    examined. It returns the set of OIDs of databases that have objects stored
12409    in the tablespace. If this function returns any rows, the tablespace is not
12410    empty and cannot be dropped. To display the specific objects populating the
12411    tablespace, you will need to connect to the databases identified by
12412    <function>pg_tablespace_databases</function> and query their
12413    <structname>pg_class</> catalogs.
12414   </para>
12415
12416   <para>
12417    <function>pg_typeof</function> returns the OID of the data type of the
12418    value that is passed to it.  This can be helpful for troubleshooting or
12419    dynamically constructing SQL queries.  The function is declared as
12420    returning <type>regtype</>, which is an OID alias type (see
12421    <xref linkend="datatype-oid">); this means that it is the same as an
12422    OID for comparison purposes but displays as a type name.  For example:
12423 <programlisting>
12424 SELECT pg_typeof(33);
12425
12426  pg_typeof 
12427 -----------
12428  integer
12429 (1 row)
12430
12431 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
12432  typlen 
12433 --------
12434       4
12435 (1 row)
12436 </programlisting>
12437   </para>
12438
12439    <indexterm>
12440     <primary>col_description</primary>
12441    </indexterm>
12442
12443    <indexterm>
12444     <primary>obj_description</primary>
12445    </indexterm>
12446
12447    <indexterm>
12448     <primary>shobj_description</primary>
12449    </indexterm>
12450
12451    <indexterm>
12452     <primary>comment</primary>
12453     <secondary sortas="database objects">about database objects</secondary>
12454    </indexterm>
12455
12456    <para>
12457     The functions shown in <xref linkend="functions-info-comment-table">
12458     extract comments previously stored with the <xref linkend="sql-comment"
12459     endterm="sql-comment-title"> command.  A null value is returned if no
12460     comment could be found for the specified parameters.
12461    </para>
12462
12463    <table id="functions-info-comment-table">
12464     <title>Comment Information Functions</title>
12465     <tgroup cols="3">
12466      <thead>
12467       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12468      </thead>
12469
12470      <tbody>
12471       <row>
12472        <entry><literal><function>col_description</function>(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</literal></entry>
12473        <entry><type>text</type></entry>
12474        <entry>get comment for a table column</entry>
12475       </row>
12476       <row>
12477        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12478        <entry><type>text</type></entry>
12479        <entry>get comment for a database object</entry>
12480       </row>
12481       <row>
12482        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>)</literal></entry>
12483        <entry><type>text</type></entry>
12484        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
12485       </row>
12486       <row>
12487        <entry><literal><function>shobj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12488        <entry><type>text</type></entry>
12489        <entry>get comment for a shared database object</entry>
12490       </row>
12491      </tbody>
12492     </tgroup>
12493    </table>
12494
12495    <para>
12496     <function>col_description</function> returns the comment for a table column,
12497     which is specified by the OID of its table and its column number.
12498     <function>obj_description</function> cannot be used for table columns since
12499     columns do not have OIDs of their own.
12500    </para>
12501
12502    <para>
12503     The two-parameter form of <function>obj_description</function> returns the
12504     comment for a database object specified by its OID and the name of the
12505     containing system catalog.  For example,
12506     <literal>obj_description(123456,'pg_class')</literal>
12507     would retrieve the comment for the table with OID 123456.
12508     The one-parameter form of <function>obj_description</function> requires only
12509     the object OID.  It is deprecated since there is no guarantee that
12510     OIDs are unique across different system catalogs; therefore, the wrong
12511     comment might be returned.
12512    </para>
12513
12514    <para>
12515     <function>shobj_description</function> is used just like
12516     <function>obj_description</function> except it is used for retrieving
12517     comments on shared objects.  Some system catalogs are global to all
12518     databases within each cluster and their descriptions are stored globally
12519     as well.
12520    </para>
12521
12522    <indexterm>
12523     <primary>txid_current</primary>
12524    </indexterm>
12525
12526    <indexterm>
12527     <primary>txid_current_snapshot</primary>
12528    </indexterm>
12529
12530    <indexterm>
12531     <primary>txid_snapshot_xmin</primary>
12532    </indexterm>
12533
12534    <indexterm>
12535     <primary>txid_snapshot_xmax</primary>
12536    </indexterm>
12537
12538    <indexterm>
12539     <primary>txid_snapshot_xip</primary>
12540    </indexterm>
12541
12542    <indexterm>
12543     <primary>txid_visible_in_snapshot</primary>
12544    </indexterm>
12545
12546    <para>
12547     The functions shown in <xref linkend="functions-txid-snapshot">
12548     export server transaction information.  The main
12549     use of these functions is to determine which transactions were committed
12550     between two snapshots.
12551    </para>
12552
12553    <table id="functions-txid-snapshot">
12554     <title>Transaction IDs and snapshots</title>
12555     <tgroup cols="3">
12556      <thead>
12557       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12558      </thead>
12559
12560      <tbody>
12561       <row>
12562        <entry><literal><function>txid_current</function>()</literal></entry>
12563        <entry><type>bigint</type></entry>
12564        <entry>get current transaction ID</entry>
12565       </row>
12566       <row>
12567        <entry><literal><function>txid_current_snapshot</function>()</literal></entry>
12568        <entry><type>txid_snapshot</type></entry>
12569        <entry>get current snapshot</entry>
12570       </row>
12571       <row>
12572        <entry><literal><function>txid_snapshot_xmin</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12573        <entry><type>bigint</type></entry>
12574        <entry>get xmin of snapshot</entry>
12575       </row>
12576       <row>
12577        <entry><literal><function>txid_snapshot_xmax</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12578        <entry><type>bigint</type></entry>
12579        <entry>get xmax of snapshot</entry>
12580       </row>
12581       <row>
12582        <entry><literal><function>txid_snapshot_xip</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12583        <entry><type>setof bigint</type></entry>
12584        <entry>get in-progress transaction IDs in snapshot</entry>
12585       </row>
12586       <row>
12587        <entry><literal><function>txid_visible_in_snapshot</function>(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</literal></entry>
12588        <entry><type>boolean</type></entry>
12589        <entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
12590       </row>
12591      </tbody>
12592     </tgroup>
12593    </table>
12594
12595    <para>
12596     The internal transaction ID type (<type>xid</>) is 32 bits wide and
12597     wraps around every 4 billion transactions.  However, these functions
12598     export a 64-bit format that is extended with an <quote>epoch</> counter
12599     so it will not wrap around during the life of an installation.
12600     The data type used by these functions, <type>txid_snapshot</type>,
12601     stores information about transaction ID
12602     visibility at a particular moment in time.  Its components are
12603     described in <xref linkend="functions-txid-snapshot-parts">.
12604    </para>
12605
12606    <table id="functions-txid-snapshot-parts">
12607     <title>Snapshot components</title>
12608     <tgroup cols="2">
12609      <thead>
12610       <row>
12611        <entry>Name</entry>
12612        <entry>Description</entry>
12613       </row>
12614      </thead>
12615
12616      <tbody>
12617
12618       <row>
12619        <entry><type>xmin</type></entry>
12620        <entry>
12621          Earliest transaction ID (txid) that is still active.  All earlier
12622          transactions will either be committed and visible, or rolled
12623          back and dead.
12624        </entry>
12625       </row>
12626
12627       <row>
12628        <entry><type>xmax</type></entry>
12629        <entry>
12630         First as-yet-unassigned txid.  All txids later than this are
12631         not yet started as of the time of the snapshot, and thus invisible.
12632        </entry>
12633       </row>
12634
12635       <row>
12636        <entry><type>xip_list</type></entry>
12637        <entry>
12638         Active txids at the time of the snapshot.  The list
12639         includes only those active txids between <literal>xmin</>
12640         and <literal>xmax</>; there might be active txids higher
12641         than xmax.  A txid that is <literal>xmin &lt;= txid &lt;
12642         xmax</literal> and not in this list was already completed
12643         at the time of the snapshot, and thus either visible or
12644         dead according to its commit status.  The list does not
12645         include txids of subtransactions.
12646        </entry>
12647       </row>
12648
12649      </tbody>
12650     </tgroup>
12651    </table>
12652
12653    <para>
12654     <type>txid_snapshot</>'s textual representation is
12655     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
12656     For example <literal>10:20:10,14,15</literal> means
12657     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
12658    </para>
12659   </sect1>
12660
12661   <sect1 id="functions-admin">
12662    <title>System Administration Functions</title>
12663
12664    <para>
12665     <xref linkend="functions-admin-set-table"> shows the functions
12666     available to query and alter run-time configuration parameters.
12667    </para>
12668
12669    <table id="functions-admin-set-table">
12670     <title>Configuration Settings Functions</title>
12671     <tgroup cols="3">
12672      <thead>
12673       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12674      </thead>
12675
12676      <tbody>
12677       <row>
12678        <entry>
12679         <literal><function>current_setting</function>(<parameter>setting_name</parameter>)</literal>
12680        </entry>
12681        <entry><type>text</type></entry>
12682        <entry>get current value of setting</entry>
12683       </row>
12684       <row>
12685        <entry>
12686         <literal><function>set_config(<parameter>setting_name</parameter>,
12687                              <parameter>new_value</parameter>,
12688                              <parameter>is_local</parameter>)</function></literal>
12689        </entry>
12690        <entry><type>text</type></entry>
12691        <entry>set parameter and return new value</entry>
12692       </row>
12693      </tbody>
12694     </tgroup>
12695    </table>
12696
12697    <indexterm>
12698     <primary>SET</primary>
12699    </indexterm>
12700
12701    <indexterm>
12702     <primary>SHOW</primary>
12703    </indexterm>
12704
12705    <indexterm>
12706     <primary>configuration</primary>
12707     <secondary sortas="server">of the server</secondary>
12708     <tertiary>functions</tertiary>
12709    </indexterm>
12710
12711    <para>
12712     The function <function>current_setting</function> yields the
12713     current value of the setting <parameter>setting_name</parameter>.
12714     It corresponds to the <acronym>SQL</acronym> command
12715     <command>SHOW</command>.  An example:
12716 <programlisting>
12717 SELECT current_setting('datestyle');
12718
12719  current_setting
12720 -----------------
12721  ISO, MDY
12722 (1 row)
12723 </programlisting>
12724    </para>
12725
12726    <para>
12727     <function>set_config</function> sets the parameter
12728     <parameter>setting_name</parameter> to
12729     <parameter>new_value</parameter>.  If
12730     <parameter>is_local</parameter> is <literal>true</literal>, the
12731     new value will only apply to the current transaction. If you want
12732     the new value to apply for the current session, use
12733     <literal>false</literal> instead. The function corresponds to the
12734     SQL command <command>SET</command>. An example:
12735 <programlisting>
12736 SELECT set_config('log_statement_stats', 'off', false);
12737
12738  set_config
12739 ------------
12740  off
12741 (1 row)
12742 </programlisting>
12743    </para>
12744
12745    <indexterm>
12746     <primary>pg_cancel_backend</primary>
12747    </indexterm>
12748    <indexterm>
12749     <primary>pg_terminate_backend</primary>
12750    </indexterm>
12751    <indexterm>
12752     <primary>pg_reload_conf</primary>
12753    </indexterm>
12754    <indexterm>
12755     <primary>pg_rotate_logfile</primary>
12756    </indexterm>
12757
12758    <indexterm>
12759     <primary>signal</primary>
12760     <secondary sortas="backend">backend processes</secondary>
12761    </indexterm>
12762
12763    <para>
12764     The functions shown in <xref
12765     linkend="functions-admin-signal-table"> send control signals to
12766     other server processes.  Use of these functions is restricted
12767     to superusers.
12768    </para>
12769
12770    <table id="functions-admin-signal-table">
12771     <title>Server Signalling Functions</title>
12772     <tgroup cols="3">
12773      <thead>
12774       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12775       </row>
12776      </thead>
12777
12778      <tbody>
12779       <row>
12780        <entry>
12781         <literal><function>pg_cancel_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12782         </entry>
12783        <entry><type>boolean</type></entry>
12784        <entry>Cancel a backend's current query</entry>
12785       </row>
12786       <row>
12787        <entry>
12788         <literal><function>pg_terminate_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12789         </entry>
12790        <entry><type>boolean</type></entry>
12791        <entry>Terminate a backend</entry>
12792       </row>
12793       <row>
12794        <entry>
12795         <literal><function>pg_reload_conf</function>()</literal>
12796         </entry>
12797        <entry><type>boolean</type></entry>
12798        <entry>Cause server processes to reload their configuration files</entry>
12799       </row>
12800       <row>
12801        <entry>
12802         <literal><function>pg_rotate_logfile</function>()</literal>
12803         </entry>
12804        <entry><type>boolean</type></entry>
12805        <entry>Rotate server's log file</entry>
12806       </row>
12807      </tbody>
12808     </tgroup>
12809    </table>
12810
12811    <para>
12812     Each of these functions returns <literal>true</literal> if
12813     successful and <literal>false</literal> otherwise.
12814    </para>
12815
12816    <para>
12817     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
12818     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
12819     respectively) to backend processes identified by process ID.
12820     The process ID of an active backend can be found from
12821     the <structfield>procpid</structfield> column of the
12822     <structname>pg_stat_activity</structname> view, or by listing the
12823     <command>postgres</command> processes on the server using
12824     <application>ps</> on Unix or the <application>Task
12825     Manager</> on <productname>Windows</>.
12826    </para>
12827
12828    <para>
12829     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
12830     to the server, causing configuration files
12831     to be reloaded by all server processes.
12832    </para>
12833
12834    <para>
12835     <function>pg_rotate_logfile</> signals the log-file manager to switch
12836     to a new output file immediately.  This works only when the built-in
12837     log collector is running, since otherwise there is no log-file manager 
12838     subprocess.
12839    </para>
12840
12841    <indexterm>
12842     <primary>pg_start_backup</primary>
12843    </indexterm>
12844    <indexterm>
12845     <primary>pg_stop_backup</primary>
12846    </indexterm>
12847    <indexterm>
12848     <primary>pg_switch_xlog</primary>
12849    </indexterm>
12850    <indexterm>
12851     <primary>pg_current_xlog_location</primary>
12852    </indexterm>
12853    <indexterm>
12854     <primary>pg_current_xlog_insert_location</primary>
12855    </indexterm>
12856    <indexterm>
12857     <primary>pg_xlogfile_name_offset</primary>
12858    </indexterm>
12859    <indexterm>
12860     <primary>pg_xlogfile_name</primary>
12861    </indexterm>
12862    <indexterm>
12863     <primary>backup</primary>
12864    </indexterm>
12865
12866    <para>
12867     The functions shown in <xref
12868     linkend="functions-admin-backup-table"> assist in making on-line backups.
12869     Use of the first three functions is restricted to superusers.
12870    </para>
12871
12872    <table id="functions-admin-backup-table">
12873     <title>Backup Control Functions</title>
12874     <tgroup cols="3">
12875      <thead>
12876       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12877       </row>
12878      </thead>
12879
12880      <tbody>
12881       <row>
12882        <entry>
12883         <literal><function>pg_start_backup</function>(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> </optional>)</literal>
12884         </entry>
12885        <entry><type>text</type></entry>
12886        <entry>Prepare for performing on-line backup</entry>
12887       </row>
12888       <row>
12889        <entry>
12890         <literal><function>pg_stop_backup</function>()</literal>
12891         </entry>
12892        <entry><type>text</type></entry>
12893        <entry>Finalize after performing on-line backup</entry>
12894       </row>
12895       <row>
12896        <entry>
12897         <literal><function>pg_switch_xlog</function>()</literal>
12898         </entry>
12899        <entry><type>text</type></entry>
12900        <entry>Force switch to a new transaction log file</entry>
12901       </row>
12902       <row>
12903        <entry>
12904         <literal><function>pg_current_xlog_location</function>()</literal>
12905         </entry>
12906        <entry><type>text</type></entry>
12907        <entry>Get current transaction log write location</entry>
12908       </row>
12909       <row>
12910        <entry>
12911         <literal><function>pg_current_xlog_insert_location</function>()</literal>
12912         </entry>
12913        <entry><type>text</type></entry>
12914        <entry>Get current transaction log insert location</entry>
12915       </row>
12916       <row>
12917        <entry>
12918         <literal><function>pg_xlogfile_name_offset</function>(<parameter>location</> <type>text</>)</literal>
12919         </entry>
12920        <entry><type>text</>, <type>integer</></entry>
12921        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
12922       </row>
12923       <row>
12924        <entry>
12925         <literal><function>pg_xlogfile_name</function>(<parameter>location</> <type>text</>)</literal>
12926         </entry>
12927        <entry><type>text</type></entry>
12928        <entry>Convert transaction log location string to file name</entry>
12929       </row>
12930      </tbody>
12931     </tgroup>
12932    </table>
12933
12934    <para>
12935     <function>pg_start_backup</> accepts an
12936     arbitrary user-defined label for the backup.  (Typically this would be
12937     the name under which the backup dump file will be stored.)  The function
12938     writes a backup label file (<filename>backup_label</>) into the
12939     database cluster's data directory, performs a checkpoint,
12940     and then returns the backup's starting transaction log location as text.
12941     The user can ignore this result value, but it is
12942     provided in case it is useful.
12943 <programlisting>
12944 postgres=# select pg_start_backup('label_goes_here');
12945  pg_start_backup
12946 -----------------
12947  0/D4445B8
12948 (1 row)
12949 </programlisting>
12950     There is an optional boolean second parameter.  If <literal>true</>,
12951     it specifies executing <function>pg_start_backup</> as quickly as
12952     possible.  This forces an immediate checkpoint which will cause a
12953     spike in I/O operations, slowing any concurrently executing queries.
12954    </para>
12955
12956    <para>
12957     <function>pg_stop_backup</> removes the label file created by
12958     <function>pg_start_backup</>, and creates a backup history file in
12959     the transaction log archive area.  The history file includes the label given to
12960     <function>pg_start_backup</>, the starting and ending transaction log locations for
12961     the backup, and the starting and ending times of the backup.  The return
12962     value is the backup's ending transaction log location (which again
12963     can be ignored).  After recording the ending location, the current
12964     transaction log insertion
12965     point is automatically advanced to the next transaction log file, so that the
12966     ending transaction log file can be archived immediately to complete the backup.
12967    </para>
12968
12969    <para>
12970     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the
12971     current file to be archived (assuming you are using continuous archiving).
12972     The return value is the ending transaction log location + 1 within the just-completed transaction log file.
12973     If there has been no transaction log activity since the last transaction log switch,
12974     <function>pg_switch_xlog</> does nothing and returns the start location
12975     of the transaction log file currently in use.
12976    </para>
12977
12978    <para>
12979     <function>pg_current_xlog_location</> displays the current transaction log write
12980     location in the format used by the above functions.  Similarly,
12981     <function>pg_current_xlog_insert_location</> displays the current transaction log
12982     insertion point.  The insertion point is the <quote>logical</> end
12983     of the transaction log
12984     at any instant, while the write location is the end of what has actually
12985     been written out from the server's internal buffers.  The write location
12986     is the end of what can be examined from outside the server, and is usually
12987     what you want if you are interested in archiving partially-complete transaction log
12988     files.  The insertion point is made available primarily for server
12989     debugging purposes.  These are both read-only operations and do not
12990     require superuser permissions.
12991    </para>
12992
12993    <para>
12994     You can use <function>pg_xlogfile_name_offset</> to extract the
12995     corresponding transaction log file name and byte offset from the results of any of the
12996     above functions.  For example:
12997 <programlisting>
12998 postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup());
12999         file_name         | file_offset 
13000 --------------------------+-------------
13001  00000001000000000000000D |     4039624
13002 (1 row)
13003 </programlisting>
13004     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
13005     When the given transaction log location is exactly at a transaction log file boundary, both
13006     these functions return the name of the preceding transaction log file.
13007     This is usually the desired behavior for managing transaction log archiving
13008     behavior, since the preceding file is the last one that currently
13009     needs to be archived.
13010    </para>
13011
13012    <para>
13013     For details about proper usage of these functions, see
13014     <xref linkend="continuous-archiving">.
13015    </para>
13016
13017    <para>
13018     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
13019     the disk space usage of database objects.
13020    </para>
13021
13022    <indexterm>
13023     <primary>pg_column_size</primary>
13024    </indexterm>
13025    <indexterm>
13026     <primary>pg_database_size</primary>
13027    </indexterm>
13028    <indexterm>
13029     <primary>pg_relation_size</primary>
13030    </indexterm>
13031    <indexterm>
13032     <primary>pg_size_pretty</primary>
13033    </indexterm>
13034    <indexterm>
13035     <primary>pg_tablespace_size</primary>
13036    </indexterm>
13037    <indexterm>
13038     <primary>pg_total_relation_size</primary>
13039    </indexterm>
13040
13041    <table id="functions-admin-dbsize">
13042     <title>Database Object Size Functions</title>
13043     <tgroup cols="3">
13044      <thead>
13045       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13046       </row>
13047      </thead>
13048
13049      <tbody>
13050       <row>
13051        <entry><literal><function>pg_column_size</function>(<type>any</type>)</literal></entry>
13052        <entry><type>int</type></entry>
13053        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
13054       </row>
13055       <row>
13056        <entry>
13057         <literal><function>pg_database_size</function>(<type>oid</type>)</literal>
13058         </entry>
13059        <entry><type>bigint</type></entry>
13060        <entry>Disk space used by the database with the specified OID</entry>
13061       </row>
13062       <row>
13063        <entry>
13064         <literal><function>pg_database_size</function>(<type>name</type>)</literal>
13065         </entry>
13066        <entry><type>bigint</type></entry>
13067        <entry>Disk space used by the database with the specified name</entry>
13068       </row>
13069       <row>
13070        <entry>
13071         <literal><function>pg_relation_size</function>(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</literal>
13072         </entry>
13073        <entry><type>bigint</type></entry>
13074        <entry>
13075         Disk space used by the specified fork, <literal>'main'</literal> or
13076         <literal>'fsm'</literal>, of a table or index with the specified OID
13077         or name; the table name can be schema-qualified.
13078        </entry>
13079       </row>
13080       <row>
13081        <entry>
13082         <literal><function>pg_relation_size</function>(<parameter>relation</parameter> <type>regclass</type>)</literal>
13083         </entry>
13084        <entry><type>bigint</type></entry>
13085        <entry>
13086         Shorthand for <literal>pg_relation_size(..., 'main')</literal>
13087        </entry>
13088       </row>
13089       <row>
13090        <entry>
13091         <literal><function>pg_size_pretty</function>(<type>bigint</type>)</literal>
13092         </entry>
13093        <entry><type>text</type></entry>
13094        <entry>Converts a size in bytes into a human-readable format with size units</entry>
13095       </row>
13096       <row>
13097        <entry>
13098         <literal><function>pg_tablespace_size</function>(<type>oid</type>)</literal>
13099         </entry>
13100        <entry><type>bigint</type></entry>
13101        <entry>Disk space used by the tablespace with the specified OID</entry>
13102       </row>
13103       <row>
13104        <entry>
13105         <literal><function>pg_tablespace_size</function>(<type>name</type>)</literal>
13106         </entry>
13107        <entry><type>bigint</type></entry>
13108        <entry>Disk space used by the tablespace with the specified name</entry>
13109       </row>
13110       <row>
13111        <entry>
13112         <literal><function>pg_total_relation_size</function>(<type>regclass</type>)</literal>
13113         </entry>
13114        <entry><type>bigint</type></entry>
13115        <entry>
13116         Total disk space used by the table with the specified OID or name,
13117         including indexes and <acronym>TOAST</> data; the table name can be
13118         schema-qualified.
13119        </entry>
13120       </row>
13121      </tbody>
13122     </tgroup>
13123    </table>
13124
13125    <para>
13126     <function>pg_column_size</> shows the space used to store any individual
13127     data value.
13128    </para>
13129
13130    <para>
13131     <function>pg_database_size</function> and <function>pg_tablespace_size</>
13132     accept the OID or name of a database or tablespace, and return the total
13133     disk space used therein.
13134    </para>
13135
13136    <para>
13137     <function>pg_relation_size</> accepts the OID or name of a table, index or
13138     toast table, and returns the size in bytes. Specifying
13139     <literal>'main'</literal> or leaving out the second argument returns the
13140     size of the main data fork of the relation. Specifying
13141     <literal>'fsm'</literal> returns the size of the
13142     Free Space Map (see <xref linkend="storage-fsm">) associated with the
13143     relation.
13144    </para>
13145
13146    <para>
13147     <function>pg_size_pretty</> can be used to format the result of one of
13148     the other functions in a human-readable way, using kB, MB, GB or TB as
13149     appropriate.
13150    </para>
13151
13152    <para>
13153     <function>pg_total_relation_size</> accepts the OID or name of a
13154     table or toast table, and returns the size in bytes of the data
13155     and all associated indexes and toast tables.
13156    </para>
13157
13158    <para>
13159     The functions shown in <xref
13160     linkend="functions-admin-genfile"> provide native access to
13161     files on the machine hosting the server. Only files within the
13162     database cluster directory and the <varname>log_directory</> can be
13163     accessed.  Use a relative path for files in the cluster directory,
13164     and a path matching the <varname>log_directory</> configuration setting
13165     for log files.  Use of these functions is restricted to superusers.
13166    </para>
13167
13168    <table id="functions-admin-genfile">
13169     <title>Generic File Access Functions</title>
13170     <tgroup cols="3">
13171      <thead>
13172       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13173       </row>
13174      </thead>
13175
13176      <tbody>
13177       <row>
13178        <entry>
13179         <literal><function>pg_ls_dir</function>(<parameter>dirname</> <type>text</>)</literal>
13180        </entry>
13181        <entry><type>setof text</type></entry>
13182        <entry>List the contents of a directory</entry>
13183       </row>
13184       <row>
13185        <entry>
13186         <literal><function>pg_read_file</function>(<parameter>filename</> <type>text</>, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>)</literal>
13187        </entry>
13188        <entry><type>text</type></entry>
13189        <entry>Return the contents of a text file</entry>
13190       </row>
13191       <row>
13192        <entry>
13193         <literal><function>pg_stat_file</function>(<parameter>filename</> <type>text</>)</literal>
13194        </entry>
13195        <entry><type>record</type></entry>
13196        <entry>Return information about a file</entry>
13197       </row>
13198      </tbody>
13199     </tgroup>
13200    </table>
13201
13202    <indexterm>
13203     <primary>pg_ls_dir</primary>
13204    </indexterm>
13205    <para>
13206     <function>pg_ls_dir</> returns all the names in the specified
13207     directory, except the special entries <quote><literal>.</></> and
13208     <quote><literal>..</></>.
13209    </para>
13210
13211    <indexterm>
13212     <primary>pg_read_file</primary>
13213    </indexterm>
13214    <para>
13215     <function>pg_read_file</> returns part of a text file, starting
13216     at the given <parameter>offset</>, returning at most <parameter>length</>
13217     bytes (less if the end of file is reached first).  If <parameter>offset</>
13218     is negative, it is relative to the end of the file.
13219    </para>
13220
13221    <indexterm>
13222     <primary>pg_stat_file</primary>
13223    </indexterm>
13224    <para>
13225     <function>pg_stat_file</> returns a record containing the file
13226     size, last accessed time stamp, last modified time stamp,
13227     last file status change time stamp (Unix platforms only),
13228     file creation time stamp (Windows only), and a <type>boolean</type>
13229     indicating if it is a directory.  Typical usage include:
13230 <programlisting>
13231 SELECT * FROM pg_stat_file('filename');
13232 SELECT (pg_stat_file('filename')).modification;
13233 </programlisting>
13234    </para>
13235
13236    <para>
13237     The functions shown in <xref linkend="functions-advisory-locks"> manage
13238     advisory locks.  For details about proper use of these functions, see
13239     <xref linkend="advisory-locks">.
13240    </para>
13241
13242    <table id="functions-advisory-locks">
13243     <title>Advisory Lock Functions</title>
13244     <tgroup cols="3">
13245      <thead>
13246       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13247       </row>
13248      </thead>
13249
13250      <tbody>
13251       <row>
13252        <entry>
13253         <literal><function>pg_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
13254        </entry>
13255        <entry><type>void</type></entry>
13256        <entry>Obtain exclusive advisory lock</entry>
13257       </row>
13258       <row>
13259        <entry>
13260         <literal><function>pg_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13261        </entry>
13262        <entry><type>void</type></entry>
13263        <entry>Obtain exclusive advisory lock</entry>
13264       </row>
13265
13266       <row>
13267        <entry>
13268         <literal><function>pg_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
13269        </entry>
13270        <entry><type>void</type></entry>
13271        <entry>Obtain shared advisory lock</entry>
13272       </row>
13273       <row>
13274        <entry>
13275         <literal><function>pg_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13276        </entry>
13277        <entry><type>void</type></entry>
13278        <entry>Obtain shared advisory lock</entry>
13279       </row>
13280
13281       <row>
13282        <entry>
13283         <literal><function>pg_try_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
13284        </entry>
13285        <entry><type>boolean</type></entry>
13286        <entry>Obtain exclusive advisory lock if available</entry>
13287       </row>
13288       <row>
13289        <entry>
13290         <literal><function>pg_try_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13291        </entry>
13292        <entry><type>boolean</type></entry>
13293        <entry>Obtain exclusive advisory lock if available</entry>
13294       </row>
13295
13296       <row>
13297        <entry>
13298         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
13299        </entry>
13300        <entry><type>boolean</type></entry>
13301        <entry>Obtain shared advisory lock if available</entry>
13302       </row>
13303       <row>
13304        <entry>
13305         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13306        </entry>
13307        <entry><type>boolean</type></entry>
13308        <entry>Obtain shared advisory lock if available</entry>
13309       </row>
13310
13311       <row>
13312        <entry>
13313         <literal><function>pg_advisory_unlock</function>(<parameter>key</> <type>bigint</>)</literal>
13314        </entry>
13315        <entry><type>boolean</type></entry>
13316        <entry>Release an exclusive advisory lock</entry>
13317       </row>
13318       <row>
13319        <entry>
13320         <literal><function>pg_advisory_unlock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13321        </entry>
13322        <entry><type>boolean</type></entry>
13323        <entry>Release an exclusive advisory lock</entry>
13324       </row>
13325
13326       <row>
13327        <entry>
13328         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
13329        </entry>
13330        <entry><type>boolean</type></entry>
13331        <entry>Release a shared advisory lock</entry>
13332       </row>
13333       <row>
13334        <entry>
13335         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13336        </entry>
13337        <entry><type>boolean</type></entry>
13338        <entry>Release a shared advisory lock</entry>
13339       </row>
13340
13341       <row>
13342        <entry>
13343         <literal><function>pg_advisory_unlock_all</function>()</literal>
13344        </entry>
13345        <entry><type>void</type></entry>
13346        <entry>Release all advisory locks held by the current session</entry>
13347       </row>
13348
13349      </tbody>
13350     </tgroup>
13351    </table>
13352
13353    <indexterm>
13354     <primary>pg_advisory_lock</primary>
13355    </indexterm>
13356    <para>
13357     <function>pg_advisory_lock</> locks an application-defined resource,
13358     which can be identified either by a single 64-bit key value or two
13359     32-bit key values (note that these two key spaces do not overlap). 
13360     The key type is specified in <literal>pg_locks.objid</>.  If
13361     another session already holds a lock on the same resource, the
13362     function will wait until the resource becomes available.  The lock
13363     is exclusive.  Multiple lock requests stack, so that if the same resource
13364     is locked three times it must be also unlocked three times to be
13365     released for other sessions' use.
13366    </para>
13367
13368    <indexterm>
13369     <primary>pg_advisory_lock_shared</primary>
13370    </indexterm>
13371    <para>
13372     <function>pg_advisory_lock_shared</> works the same as
13373     <function>pg_advisory_lock</>,
13374     except the lock can be shared with other sessions requesting shared locks.
13375     Only would-be exclusive lockers are locked out.
13376    </para>
13377
13378    <indexterm>
13379     <primary>pg_try_advisory_lock</primary>
13380    </indexterm>
13381    <para>
13382     <function>pg_try_advisory_lock</> is similar to
13383     <function>pg_advisory_lock</>, except the function will not wait for the
13384     lock to become available.  It will either obtain the lock immediately and
13385     return <literal>true</>, or return <literal>false</> if the lock cannot be
13386     acquired immediately.
13387    </para>
13388
13389    <indexterm>
13390     <primary>pg_try_advisory_lock_shared</primary>
13391    </indexterm>
13392    <para>
13393     <function>pg_try_advisory_lock_shared</> works the same as
13394     <function>pg_try_advisory_lock</>, except it attempts to acquire
13395     a shared rather than an exclusive lock.
13396    </para>
13397
13398    <indexterm>
13399     <primary>pg_advisory_unlock</primary>
13400    </indexterm>
13401    <para>
13402     <function>pg_advisory_unlock</> will release a previously-acquired
13403     exclusive advisory lock.  It
13404     returns <literal>true</> if the lock is successfully released.
13405     If the lock was not held, it will return <literal>false</>,
13406     and in addition, an SQL warning will be raised by the server.
13407    </para>
13408
13409    <indexterm>
13410     <primary>pg_advisory_unlock_shared</primary>
13411    </indexterm>
13412    <para>
13413     <function>pg_advisory_unlock_shared</> works the same as
13414     <function>pg_advisory_unlock</>, 
13415     except is releases a shared advisory lock.
13416    </para>
13417
13418    <indexterm>
13419     <primary>pg_advisory_unlock_all</primary>
13420    </indexterm>
13421    <para>
13422     <function>pg_advisory_unlock_all</> will release all advisory locks
13423     held by the current session.  (This function is implicitly invoked
13424     at session end, even if the client disconnects abruptly.)
13425    </para>
13426
13427   </sect1>
13428
13429   <sect1 id="functions-trigger">
13430    <title>Trigger Functions</title>
13431
13432    <indexterm>
13433      <primary>suppress_redundant_updates_trigger</primary>
13434    </indexterm>
13435
13436    <para>
13437       Currently <productname>PostgreSQL</> provides one built in trigger
13438       function, <function>suppress_redundant_updates_trigger</>, 
13439       which will prevent any update
13440       that does not actually change the data in the row from taking place, in
13441       contrast to the normal behaviour which always performs the update
13442       regardless of whether or not the data has changed. (This normal behaviour
13443       makes updates run faster, since no checking is required, and is also
13444       useful in certain cases.)
13445     </para>
13446
13447     <para>
13448       Ideally, you should normally avoid running updates that don't actually
13449       change the data in the record. Redundant updates can cost considerable
13450       unnecessary time, especially if there are lots of indexes to alter,
13451       and space in dead rows that will eventually have to be vacuumed.
13452       However, detecting such situations in client code is not
13453       always easy, or even possible, and writing expressions to detect
13454       them can be error-prone. An alternative is to use 
13455       <function>suppress_redundant_updates_trigger</>, which will skip
13456       updates that don't change the data. You should use this with care,
13457       however. The trigger takes a small but non-trivial time for each record, 
13458       so if most of the records affected by an update are actually changed,
13459       use of this trigger will actually make the update run slower.
13460     </para>
13461
13462     <para>
13463       The <function>suppress_redundant_updates_trigger</> function can be 
13464       added to a table like this:
13465 <programlisting>
13466 CREATE TRIGGER z_min_update 
13467 BEFORE UPDATE ON tablename
13468 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
13469 </programlisting>
13470       In most cases, you would want to fire this trigger last for each row.
13471       Bearing in mind that triggers fire in name order, you would then
13472       choose a trigger name that comes after the name of any other trigger
13473       you might have on the table.
13474     </para>
13475     <para>
13476        For more information about creating triggers, see
13477         <xref linkend="SQL-CREATETRIGGER">.
13478     </para>
13479   </sect1>
13480 </chapter>