]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
Support EEEE (scientific notation) in to_char().
[postgresql] / doc / src / sgml / func.sgml
1 <!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.486 2009/08/10 18:29:26 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     Notice that <token>BETWEEN</token> treats the endpoint values as included
272     in the range.
273     <literal>NOT BETWEEN</literal> does the opposite comparison:
274 <synopsis>
275 <replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
276 </synopsis>
277     is equivalent to
278 <synopsis>
279 <replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
280 </synopsis>
281     <indexterm>
282      <primary>BETWEEN SYMMETRIC</primary>
283     </indexterm>
284     <literal>BETWEEN SYMMETRIC</> is the same as <literal>BETWEEN</>
285     except there is no requirement that the argument to the left of
286     <literal>AND</> be less than or equal to the argument on the right.
287     If it is not, those two arguments are automatically swapped, so that
288     a nonempty range is always implied.
289    </para>
290
291    <para>
292     <indexterm>
293      <primary>IS NULL</primary>
294     </indexterm>
295     <indexterm>
296      <primary>IS NOT NULL</primary>
297     </indexterm>
298     <indexterm>
299      <primary>ISNULL</primary>
300     </indexterm>
301     <indexterm>
302      <primary>NOTNULL</primary>
303     </indexterm>
304     To check whether a value is or is not null, use the constructs:
305 <synopsis>
306 <replaceable>expression</replaceable> IS NULL
307 <replaceable>expression</replaceable> IS NOT NULL
308 </synopsis>
309     or the equivalent, but nonstandard, constructs:
310 <synopsis>
311 <replaceable>expression</replaceable> ISNULL
312 <replaceable>expression</replaceable> NOTNULL
313 </synopsis>
314     <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
315    </para>
316
317    <para>
318     Do <emphasis>not</emphasis> write
319     <literal><replaceable>expression</replaceable> = NULL</literal>
320     because <literal>NULL</> is not <quote>equal to</quote>
321     <literal>NULL</>.  (The null value represents an unknown value,
322     and it is not known whether two unknown values are equal.) This
323     behavior conforms to the SQL standard.
324    </para>
325
326   <tip>
327    <para>
328     Some applications might expect that
329     <literal><replaceable>expression</replaceable> = NULL</literal>
330     returns true if <replaceable>expression</replaceable> evaluates to
331     the null value.  It is highly recommended that these applications
332     be modified to comply with the SQL standard. However, if that
333     cannot be done the <xref linkend="guc-transform-null-equals">
334     configuration variable is available. If it is enabled,
335     <productname>PostgreSQL</productname> will convert <literal>x =
336     NULL</literal> clauses to <literal>x IS NULL</literal>.
337    </para>
338   </tip>
339
340   <note>
341    <para>
342     If the <replaceable>expression</replaceable> is row-valued, then
343     <literal>IS NULL</> is true when the row expression itself is null
344     or when all the row's fields are null, while
345     <literal>IS NOT NULL</> is true when the row expression itself is non-null
346     and all the row's fields are non-null.  Because of this behavior,
347     <literal>IS NULL</> and <literal>IS NOT NULL</> do not always return
348     inverse results for row-valued expressions, i.e., a row-valued
349     expression that contains both NULL and non-null values will return false
350     for both tests.
351     This definition conforms to the SQL standard, and is a change from the
352     inconsistent behavior exhibited by <productname>PostgreSQL</productname>
353     versions prior to 8.2.
354    </para>
355   </note>
356
357    <para>
358     <indexterm>
359      <primary>IS DISTINCT FROM</primary>
360     </indexterm>
361     <indexterm>
362      <primary>IS NOT DISTINCT FROM</primary>
363     </indexterm>
364     Ordinary comparison operators yield null (signifying <quote>unknown</>),
365     not true or false, when either input is null.  For example,
366     <literal>7 = NULL</> yields null.  When this behavior is not suitable,
367     use the
368     <literal>IS <optional> NOT </> DISTINCT FROM</literal> constructs:
369 <synopsis>
370 <replaceable>expression</replaceable> IS DISTINCT FROM <replaceable>expression</replaceable>
371 <replaceable>expression</replaceable> IS NOT DISTINCT FROM <replaceable>expression</replaceable>
372 </synopsis>
373     For non-null inputs, <literal>IS DISTINCT FROM</literal> is
374     the same as the <literal>&lt;&gt;</> operator.  However, if both
375     inputs are null it returns false, and if only one input is
376     null it returns true.  Similarly, <literal>IS NOT DISTINCT
377     FROM</literal> is identical to <literal>=</literal> for non-null
378     inputs, but it returns true when both inputs are null, and false when only
379     one input is null. Thus, these constructs effectively act as though null
380     were a normal data value, rather than <quote>unknown</>.
381    </para>
382
383    <para>
384     <indexterm>
385      <primary>IS TRUE</primary>
386     </indexterm>
387     <indexterm>
388      <primary>IS NOT TRUE</primary>
389     </indexterm>
390     <indexterm>
391      <primary>IS FALSE</primary>
392     </indexterm>
393     <indexterm>
394      <primary>IS NOT FALSE</primary>
395     </indexterm>
396     <indexterm>
397      <primary>IS UNKNOWN</primary>
398     </indexterm>
399     <indexterm>
400      <primary>IS NOT UNKNOWN</primary>
401     </indexterm>
402     Boolean values can also be tested using the constructs
403 <synopsis>
404 <replaceable>expression</replaceable> IS TRUE
405 <replaceable>expression</replaceable> IS NOT TRUE
406 <replaceable>expression</replaceable> IS FALSE
407 <replaceable>expression</replaceable> IS NOT FALSE
408 <replaceable>expression</replaceable> IS UNKNOWN
409 <replaceable>expression</replaceable> IS NOT UNKNOWN
410 </synopsis>
411     These will always return true or false, never a null value, even when the
412     operand is null.
413     A null input is treated as the logical value <quote>unknown</>.
414     Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
415     effectively the same as <literal>IS NULL</literal> and
416     <literal>IS NOT NULL</literal>, respectively, except that the input
417     expression must be of Boolean type.
418    </para>
419  
420 <!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
421    <para>
422     <indexterm>
423      <primary>IS OF</primary>
424     </indexterm>
425     <indexterm>
426      <primary>IS NOT OF</primary>
427     </indexterm>
428     It is possible to check the data type of an expression using the
429     constructs
430 <synopsis>
431 <replaceable>expression</replaceable> IS OF (typename, ...)
432 <replaceable>expression</replaceable> IS NOT OF (typename, ...)
433 </synopsis>
434     They return a boolean value based on whether the expression's data
435     type is one of the listed data types.
436    </para>
437 -->
438
439   </sect1>
440
441   <sect1 id="functions-math">
442    <title>Mathematical Functions and Operators</title>
443
444    <para>
445     Mathematical operators are provided for many
446     <productname>PostgreSQL</productname> types. For types without
447     standard mathematical conventions
448     (e.g., date/time types) we
449     describe the actual behavior in subsequent sections.
450    </para>
451
452    <para>
453     <xref linkend="functions-math-op-table"> shows the available mathematical operators.
454    </para>
455
456    <table id="functions-math-op-table">
457     <title>Mathematical Operators</title>
458
459     <tgroup cols="4">
460      <thead>
461       <row>
462        <entry>Operator</entry>
463        <entry>Description</entry>
464        <entry>Example</entry>
465        <entry>Result</entry>
466       </row>
467      </thead>
468
469      <tbody>
470       <row>
471        <entry> <literal>+</literal> </entry>
472        <entry>addition</entry>
473        <entry><literal>2 + 3</literal></entry>
474        <entry><literal>5</literal></entry>
475       </row>
476
477       <row>
478        <entry> <literal>-</literal> </entry>
479        <entry>subtraction</entry>
480        <entry><literal>2 - 3</literal></entry>
481        <entry><literal>-1</literal></entry>
482       </row>
483
484       <row>
485        <entry> <literal>*</literal> </entry>
486        <entry>multiplication</entry>
487        <entry><literal>2 * 3</literal></entry>
488        <entry><literal>6</literal></entry>
489       </row>
490
491       <row>
492        <entry> <literal>/</literal> </entry>
493        <entry>division (integer division truncates the result)</entry>
494        <entry><literal>4 / 2</literal></entry>
495        <entry><literal>2</literal></entry>
496       </row>
497
498       <row>
499        <entry> <literal>%</literal> </entry>
500        <entry>modulo (remainder)</entry>
501        <entry><literal>5 % 4</literal></entry>
502        <entry><literal>1</literal></entry>
503       </row>
504
505       <row>
506        <entry> <literal>^</literal> </entry>
507        <entry>exponentiation</entry>
508        <entry><literal>2.0 ^ 3.0</literal></entry>
509        <entry><literal>8</literal></entry>
510       </row>
511
512       <row>
513        <entry> <literal>|/</literal> </entry>
514        <entry>square root</entry>
515        <entry><literal>|/ 25.0</literal></entry>
516        <entry><literal>5</literal></entry>
517       </row>
518
519       <row>
520        <entry> <literal>||/</literal> </entry>
521        <entry>cube root</entry>
522        <entry><literal>||/ 27.0</literal></entry>
523        <entry><literal>3</literal></entry>
524       </row>
525
526       <row>
527        <entry> <literal>!</literal> </entry>
528        <entry>factorial</entry>
529        <entry><literal>5 !</literal></entry>
530        <entry><literal>120</literal></entry>
531       </row>
532
533       <row>
534        <entry> <literal>!!</literal> </entry>
535        <entry>factorial (prefix operator)</entry>
536        <entry><literal>!! 5</literal></entry>
537        <entry><literal>120</literal></entry>
538       </row>
539
540       <row>
541        <entry> <literal>@</literal> </entry>
542        <entry>absolute value</entry>
543        <entry><literal>@ -5.0</literal></entry>
544        <entry><literal>5</literal></entry>
545       </row>
546
547       <row>
548        <entry> <literal>&amp;</literal> </entry>
549        <entry>bitwise AND</entry>
550        <entry><literal>91 &amp; 15</literal></entry>
551        <entry><literal>11</literal></entry>
552       </row>
553
554       <row>
555        <entry> <literal>|</literal> </entry>
556        <entry>bitwise OR</entry>
557        <entry><literal>32 | 3</literal></entry>
558        <entry><literal>35</literal></entry>
559       </row>
560
561       <row>
562        <entry> <literal>#</literal> </entry>
563        <entry>bitwise XOR</entry>
564        <entry><literal>17 # 5</literal></entry>
565        <entry><literal>20</literal></entry>
566       </row>
567
568       <row>
569        <entry> <literal>~</literal> </entry>
570        <entry>bitwise NOT</entry>
571        <entry><literal>~1</literal></entry>
572        <entry><literal>-2</literal></entry>
573       </row>
574
575       <row>
576        <entry> <literal>&lt;&lt;</literal> </entry>
577        <entry>bitwise shift left</entry>
578        <entry><literal>1 &lt;&lt; 4</literal></entry>
579        <entry><literal>16</literal></entry>
580       </row>
581
582       <row>
583        <entry> <literal>&gt;&gt;</literal> </entry>
584        <entry>bitwise shift right</entry>
585        <entry><literal>8 &gt;&gt; 2</literal></entry>
586        <entry><literal>2</literal></entry>
587       </row>
588
589      </tbody>
590     </tgroup>
591    </table>
592
593    <para>
594     The bitwise operators work only on integral data types, whereas
595     the others are available for all numeric data types.  The bitwise
596     operators are also available for the bit
597     string types <type>bit</type> and <type>bit varying</type>, as
598     shown in <xref linkend="functions-bit-string-op-table">.
599    </para>
600
601   <para>
602    <xref linkend="functions-math-func-table"> shows the available
603    mathematical functions.  In the table, <literal>dp</literal>
604    indicates <type>double precision</type>.  Many of these functions
605    are provided in multiple forms with different argument types.
606    Except where noted, any given form of a function returns the same
607    data type as its argument.
608    The functions working with <type>double precision</type> data are mostly
609    implemented on top of the host system's C library; accuracy and behavior in
610    boundary cases can therefore vary depending on the host system.
611   </para>
612
613    <indexterm>
614     <primary>abs</primary>
615    </indexterm>
616    <indexterm>
617     <primary>cbrt</primary>
618    </indexterm>
619    <indexterm>
620     <primary>ceiling</primary>
621    </indexterm>
622    <indexterm>
623     <primary>degrees</primary>
624    </indexterm>
625    <indexterm>
626     <primary>div</primary>
627    </indexterm>
628    <indexterm>
629     <primary>exp</primary>
630    </indexterm>
631    <indexterm>
632     <primary>floor</primary>
633    </indexterm>
634    <indexterm>
635     <primary>ln</primary>
636    </indexterm>
637    <indexterm>
638     <primary>log</primary>
639    </indexterm>
640    <indexterm>
641     <primary>mod</primary>
642    </indexterm>
643    <indexterm>
644     <primary>pi</primary>
645    </indexterm>
646    <indexterm>
647     <primary>power</primary>
648    </indexterm>
649    <indexterm>
650     <primary>radians</primary>
651    </indexterm>
652    <indexterm>
653     <primary>random</primary>
654    </indexterm>
655    <indexterm>
656     <primary>round</primary>
657    </indexterm>
658    <indexterm>
659     <primary>setseed</primary>
660    </indexterm>
661    <indexterm>
662     <primary>sign</primary>
663    </indexterm>
664    <indexterm>
665     <primary>sqrt</primary>
666    </indexterm>
667    <indexterm>
668     <primary>trunc</primary>
669    </indexterm>
670    <indexterm>
671     <primary>width_bucket</primary>
672    </indexterm>
673
674    <table id="functions-math-func-table">
675     <title>Mathematical Functions</title>
676     <tgroup cols="5">
677      <thead>
678       <row>
679        <entry>Function</entry>
680        <entry>Return Type</entry>
681        <entry>Description</entry>
682        <entry>Example</entry>
683        <entry>Result</entry>
684       </row>
685      </thead>
686
687      <tbody>
688       <row>
689        <entry><literal><function>abs</>(<replaceable>x</replaceable>)</literal></entry>
690        <entry>(same as input)</entry>
691        <entry>absolute value</entry>
692        <entry><literal>abs(-17.4)</literal></entry>
693        <entry><literal>17.4</literal></entry>
694       </row>
695
696       <row>
697        <entry><literal><function>cbrt</function>(<type>dp</type>)</literal></entry>
698        <entry><type>dp</type></entry>
699        <entry>cube root</entry>
700        <entry><literal>cbrt(27.0)</literal></entry>
701        <entry><literal>3</literal></entry>
702       </row>
703
704       <row>
705        <entry><literal><function>ceil</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
706        <entry>(same as input)</entry>
707        <entry>smallest integer not less than argument</entry>
708        <entry><literal>ceil(-42.8)</literal></entry>
709        <entry><literal>-42</literal></entry>
710       </row>
711
712       <row>
713        <entry><literal><function>ceiling</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
714        <entry>(same as input)</entry>
715        <entry>smallest integer not less than argument (alias for <function>ceil</function>)</entry>
716        <entry><literal>ceiling(-95.3)</literal></entry>
717        <entry><literal>-95</literal></entry>
718       </row>
719
720       <row>
721        <entry><literal><function>degrees</function>(<type>dp</type>)</literal></entry>
722        <entry><type>dp</type></entry>
723        <entry>radians to degrees</entry>
724        <entry><literal>degrees(0.5)</literal></entry>
725        <entry><literal>28.6478897565412</literal></entry>
726       </row>
727
728       <row>
729        <entry><literal><function>div</function>(<parameter>y</parameter> <type>numeric</>,
730         <parameter>x</parameter> <type>numeric</>)</literal></entry>
731        <entry><type>numeric</></entry>
732        <entry>integer quotient of <parameter>y</parameter>/<parameter>x</parameter></entry>
733        <entry><literal>div(9,4)</literal></entry>
734        <entry><literal>2</literal></entry>
735       </row>
736
737       <row>
738        <entry><literal><function>exp</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
739        <entry>(same as input)</entry>
740        <entry>exponential</entry>
741        <entry><literal>exp(1.0)</literal></entry>
742        <entry><literal>2.71828182845905</literal></entry>
743       </row>
744
745       <row>
746        <entry><literal><function>floor</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
747        <entry>(same as input)</entry>
748        <entry>largest integer not greater than argument</entry>
749        <entry><literal>floor(-42.8)</literal></entry>
750        <entry><literal>-43</literal></entry>
751       </row>
752
753       <row>
754        <entry><literal><function>ln</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
755        <entry>(same as input)</entry>
756        <entry>natural logarithm</entry>
757        <entry><literal>ln(2.0)</literal></entry>
758        <entry><literal>0.693147180559945</literal></entry>
759       </row>
760
761       <row>
762        <entry><literal><function>log</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
763        <entry>(same as input)</entry>
764        <entry>base 10 logarithm</entry>
765        <entry><literal>log(100.0)</literal></entry>
766        <entry><literal>2</literal></entry>
767       </row>
768
769       <row>
770        <entry><literal><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
771         <parameter>x</parameter> <type>numeric</type>)</literal></entry>
772        <entry><type>numeric</type></entry>
773        <entry>logarithm to base <parameter>b</parameter></entry>
774        <entry><literal>log(2.0, 64.0)</literal></entry>
775        <entry><literal>6.0000000000</literal></entry>
776       </row>
777
778       <row>
779        <entry><literal><function>mod</function>(<parameter>y</parameter>,
780         <parameter>x</parameter>)</literal></entry>
781        <entry>(same as argument types)</entry>
782        <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
783        <entry><literal>mod(9,4)</literal></entry>
784        <entry><literal>1</literal></entry>
785       </row>
786
787       <row>
788        <entry><literal><function>pi</function>()</literal></entry>
789        <entry><type>dp</type></entry>
790        <entry><quote>&pi;</quote> constant</entry>
791        <entry><literal>pi()</literal></entry>
792        <entry><literal>3.14159265358979</literal></entry>
793       </row>
794
795       <row>
796        <entry><literal><function>power</function>(<parameter>a</parameter> <type>dp</type>,
797         <parameter>b</parameter> <type>dp</type>)</literal></entry>
798        <entry><type>dp</type></entry>
799        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
800        <entry><literal>power(9.0, 3.0)</literal></entry>
801        <entry><literal>729</literal></entry>
802       </row>
803
804       <row>
805        <entry><literal><function>power</function>(<parameter>a</parameter> <type>numeric</type>,
806         <parameter>b</parameter> <type>numeric</type>)</literal></entry>
807        <entry><type>numeric</type></entry>
808        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
809        <entry><literal>power(9.0, 3.0)</literal></entry>
810        <entry><literal>729</literal></entry>
811       </row>
812
813       <row>
814        <entry><literal><function>radians</function>(<type>dp</type>)</literal></entry>
815        <entry><type>dp</type></entry>
816        <entry>degrees to radians</entry>
817        <entry><literal>radians(45.0)</literal></entry>
818        <entry><literal>0.785398163397448</literal></entry>
819       </row>
820
821       <row>
822        <entry><literal><function>random</function>()</literal></entry>
823        <entry><type>dp</type></entry>
824        <entry>random value between 0.0 and 1.0, inclusive</entry>
825        <entry><literal>random()</literal></entry>
826        <entry></entry>
827       </row>
828
829       <row>
830        <entry><literal><function>round</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
831        <entry>(same as input)</entry>
832        <entry>round to nearest integer</entry>
833        <entry><literal>round(42.4)</literal></entry>
834        <entry><literal>42</literal></entry>
835       </row>
836
837       <row>
838        <entry><literal><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
839        <entry><type>numeric</type></entry>
840        <entry>round to <parameter>s</parameter> decimal places</entry>
841        <entry><literal>round(42.4382, 2)</literal></entry>
842        <entry><literal>42.44</literal></entry>
843       </row>
844
845       <row>
846        <entry><literal><function>setseed</function>(<type>dp</type>)</literal></entry>
847        <entry><type>void</type></entry>
848        <entry>set seed for subsequent <literal>random()</literal> calls (value between -1.0 and
849        1.0, inclusive)</entry>
850        <entry><literal>setseed(0.54823)</literal></entry>
851        <entry></entry>
852       </row>
853
854       <row>
855        <entry><literal><function>sign</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
856        <entry>(same as input)</entry>
857        <entry>sign of the argument (-1, 0, +1)</entry>
858        <entry><literal>sign(-8.4)</literal></entry>
859        <entry><literal>-1</literal></entry>
860       </row>
861
862       <row>
863        <entry><literal><function>sqrt</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
864        <entry>(same as input)</entry>
865        <entry>square root</entry>
866        <entry><literal>sqrt(2.0)</literal></entry>
867        <entry><literal>1.4142135623731</literal></entry>
868       </row>
869
870       <row>
871        <entry><literal><function>trunc</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
872        <entry>(same as input)</entry>
873        <entry>truncate toward zero</entry>
874        <entry><literal>trunc(42.8)</literal></entry>
875        <entry><literal>42</literal></entry>
876       </row>
877
878       <row>
879        <entry><literal><function>trunc</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
880        <entry><type>numeric</type></entry>
881        <entry>truncate to <parameter>s</parameter> decimal places</entry>
882        <entry><literal>trunc(42.4382, 2)</literal></entry>
883        <entry><literal>42.43</literal></entry>
884       </row>
885
886       <row>
887        <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>
888        <entry><type>int</type></entry>
889        <entry>return the bucket to which <parameter>operand</> would
890        be assigned in an equidepth histogram with <parameter>count</>
891        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
892        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
893        <entry><literal>3</literal></entry>
894       </row>
895
896       <row>
897        <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>
898        <entry><type>int</type></entry>
899        <entry>return the bucket to which <parameter>operand</> would
900        be assigned in an equidepth histogram with <parameter>count</>
901        buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
902        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
903        <entry><literal>3</literal></entry>
904       </row>
905      </tbody>
906     </tgroup>
907    </table>
908
909   <para>
910    Finally, <xref linkend="functions-math-trig-table"> shows the
911    available trigonometric functions.  All trigonometric functions
912    take arguments and return values of type <type>double
913    precision</type>.
914   </para>
915
916    <indexterm>
917     <primary>acos</primary>
918    </indexterm>
919    <indexterm>
920     <primary>asin</primary>
921    </indexterm>
922    <indexterm>
923     <primary>atan</primary>
924    </indexterm>
925    <indexterm>
926     <primary>atan2</primary>
927    </indexterm>
928    <indexterm>
929     <primary>cos</primary>
930    </indexterm>
931    <indexterm>
932     <primary>cot</primary>
933    </indexterm>
934    <indexterm>
935     <primary>sin</primary>
936    </indexterm>
937    <indexterm>
938     <primary>tan</primary>
939    </indexterm>
940
941    <table id="functions-math-trig-table">
942     <title>Trigonometric Functions</title>
943
944     <tgroup cols="2">
945      <thead>
946       <row>
947        <entry>Function</entry>
948        <entry>Description</entry>
949       </row>
950      </thead>
951
952      <tbody>
953       <row>
954        <entry><literal><function>acos</function>(<replaceable>x</replaceable>)</literal></entry>
955        <entry>inverse cosine</entry>
956       </row>
957
958       <row>
959        <entry><literal><function>asin</function>(<replaceable>x</replaceable>)</literal></entry>
960        <entry>inverse sine</entry>
961       </row>
962
963       <row>
964        <entry><literal><function>atan</function>(<replaceable>x</replaceable>)</literal></entry>
965        <entry>inverse tangent</entry>
966       </row>
967
968       <row>
969        <entry><literal><function>atan2</function>(<replaceable>y</replaceable>,
970         <replaceable>x</replaceable>)</literal></entry>
971        <entry>inverse tangent of
972         <literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
973       </row>
974
975       <row>
976        <entry><literal><function>cos</function>(<replaceable>x</replaceable>)</literal></entry>
977        <entry>cosine</entry>
978       </row>
979
980       <row>
981        <entry><literal><function>cot</function>(<replaceable>x</replaceable>)</literal></entry>
982        <entry>cotangent</entry>
983       </row>
984
985       <row>
986        <entry><literal><function>sin</function>(<replaceable>x</replaceable>)</literal></entry>
987        <entry>sine</entry>
988       </row>
989
990       <row>
991        <entry><literal><function>tan</function>(<replaceable>x</replaceable>)</literal></entry>
992        <entry>tangent</entry>
993       </row>
994      </tbody>
995     </tgroup>
996    </table>
997
998   </sect1>
999
1000
1001   <sect1 id="functions-string">
1002    <title>String Functions and Operators</title>
1003
1004    <para>
1005     This section describes functions and operators for examining and
1006     manipulating string values.  Strings in this context include values
1007     of the types <type>character</type>, <type>character varying</type>,
1008     and <type>text</type>.  Unless otherwise noted, all
1009     of the functions listed below work on all of these types, but be
1010     wary of potential effects of automatic space-padding when using the
1011     <type>character</type> type.  Some functions also exist
1012     natively for the bit-string types.
1013    </para>
1014
1015    <para>
1016     <acronym>SQL</acronym> defines some string functions that use
1017     key words, rather than commas, to separate
1018     arguments.  Details are in
1019     <xref linkend="functions-string-sql">.
1020     <productname>PostgreSQL</> also provides versions of these functions
1021     that use the regular function invocation syntax
1022     (see <xref linkend="functions-string-other">).
1023    </para>
1024
1025    <note>
1026     <para>
1027      Before <productname>PostgreSQL</productname> 8.3, these functions would
1028      silently accept values of several non-string data types as well, due to
1029      the presence of implicit coercions from those data types to
1030      <type>text</>.  Those coercions have been removed because they frequently
1031      caused surprising behaviors.  However, the string concatenation operator
1032      (<literal>||</>) still accepts non-string input, so long as at least one
1033      input is of a string type, as shown in <xref
1034      linkend="functions-string-sql">.  For other cases, insert an explicit
1035      coercion to <type>text</> if you need to duplicate the previous behavior.
1036     </para>
1037    </note>
1038
1039    <indexterm>
1040     <primary>bit_length</primary>
1041    </indexterm>
1042    <indexterm>
1043     <primary>char_length</primary>
1044    </indexterm>
1045    <indexterm>
1046     <primary>lower</primary>
1047    </indexterm>
1048    <indexterm>
1049     <primary>octet_length</primary>
1050    </indexterm>
1051    <indexterm>
1052     <primary>overlay</primary>
1053    </indexterm>
1054    <indexterm>
1055     <primary>position</primary>
1056    </indexterm>
1057    <indexterm>
1058     <primary>substring</primary>
1059    </indexterm>
1060    <indexterm>
1061     <primary>trim</primary>
1062    </indexterm>
1063    <indexterm>
1064     <primary>upper</primary>
1065    </indexterm>
1066
1067    <table id="functions-string-sql">
1068     <title><acronym>SQL</acronym> String Functions and Operators</title>
1069     <tgroup cols="5">
1070      <thead>
1071       <row>
1072        <entry>Function</entry>
1073        <entry>Return Type</entry>
1074        <entry>Description</entry>
1075        <entry>Example</entry>
1076        <entry>Result</entry>  
1077       </row>
1078      </thead>
1079
1080      <tbody>
1081       <row>
1082        <entry><literal><parameter>string</parameter> <literal>||</literal>
1083         <parameter>string</parameter></literal></entry>
1084        <entry> <type>text</type> </entry>
1085        <entry>
1086         String concatenation
1087         <indexterm>
1088          <primary>character string</primary>
1089          <secondary>concatenation</secondary>
1090         </indexterm>
1091        </entry>
1092        <entry><literal>'Post' || 'greSQL'</literal></entry>
1093        <entry><literal>PostgreSQL</literal></entry>
1094       </row>
1095
1096       <row>
1097        <entry>
1098         <literal><parameter>string</parameter> <literal>||</literal>
1099         <parameter>non-string</parameter></literal>
1100         or
1101         <literal><parameter>non-string</parameter> <literal>||</literal>
1102         <parameter>string</parameter></literal>
1103        </entry>
1104        <entry> <type>text</type> </entry>
1105        <entry>
1106         String concatenation with one non-string input
1107        </entry>
1108        <entry><literal>'Value: ' || 42</literal></entry>
1109        <entry><literal>Value: 42</literal></entry>
1110       </row>
1111
1112       <row>
1113        <entry><literal><function>bit_length</function>(<parameter>string</parameter>)</literal></entry>
1114        <entry><type>int</type></entry>
1115        <entry>Number of bits in string</entry>
1116        <entry><literal>bit_length('jose')</literal></entry>
1117        <entry><literal>32</literal></entry>
1118       </row>
1119
1120       <row>
1121        <entry><literal><function>char_length</function>(<parameter>string</parameter>)</literal> or <literal><function>character_length</function>(<parameter>string</parameter>)</literal></entry>
1122        <entry><type>int</type></entry>
1123        <entry>
1124         Number of characters in string
1125         <indexterm>
1126          <primary>character string</primary>
1127          <secondary>length</secondary>
1128         </indexterm>
1129         <indexterm>
1130          <primary>length</primary>
1131          <secondary sortas="character string">of a character string</secondary>
1132          <see>character string, length</see>
1133         </indexterm>
1134        </entry>
1135        <entry><literal>char_length('jose')</literal></entry>
1136        <entry><literal>4</literal></entry>
1137       </row>
1138
1139       <row>
1140        <entry><literal><function>lower</function>(<parameter>string</parameter>)</literal></entry>
1141        <entry><type>text</type></entry>
1142        <entry>Convert string to lower case</entry>
1143        <entry><literal>lower('TOM')</literal></entry>
1144        <entry><literal>tom</literal></entry>
1145       </row>
1146
1147       <row>
1148        <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
1149        <entry><type>int</type></entry>
1150        <entry>Number of bytes in string</entry>
1151        <entry><literal>octet_length('jose')</literal></entry>
1152        <entry><literal>4</literal></entry>
1153       </row>
1154
1155       <row>
1156        <entry><literal><function>overlay</function>(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</literal></entry>
1157        <entry><type>text</type></entry>
1158        <entry>
1159         Replace substring
1160        </entry>
1161        <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
1162        <entry><literal>Thomas</literal></entry>
1163       </row>
1164
1165       <row>
1166        <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
1167        <entry><type>int</type></entry>
1168        <entry>Location of specified substring</entry>
1169        <entry><literal>position('om' in 'Thomas')</literal></entry>
1170        <entry><literal>3</literal></entry>
1171       </row>
1172
1173       <row>
1174        <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
1175        <entry><type>text</type></entry>
1176        <entry>
1177         Extract substring
1178        </entry>
1179        <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
1180        <entry><literal>hom</literal></entry>
1181       </row>
1182
1183       <row>
1184        <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</literal></entry>
1185        <entry><type>text</type></entry>
1186        <entry>
1187         Extract substring matching POSIX regular expression. See
1188         <xref linkend="functions-matching"> for more information on pattern
1189         matching.
1190        </entry>
1191        <entry><literal>substring('Thomas' from '...$')</literal></entry>
1192        <entry><literal>mas</literal></entry>
1193       </row>
1194
1195       <row>
1196        <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</literal></entry>
1197        <entry><type>text</type></entry>
1198        <entry>
1199         Extract substring matching <acronym>SQL</acronym> regular expression.
1200         See <xref linkend="functions-matching"> for more information on
1201         pattern matching.
1202        </entry>
1203        <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
1204        <entry><literal>oma</literal></entry>
1205       </row>
1206
1207       <row>
1208        <entry>
1209         <literal><function>trim</function>(<optional>leading | trailing | both</optional>
1210         <optional><parameter>characters</parameter></optional> from
1211         <parameter>string</parameter>)</literal>
1212        </entry>
1213        <entry><type>text</type></entry>
1214        <entry>
1215         Remove the longest string containing only the
1216         <parameter>characters</parameter> (a space by default) from the
1217         start/end/both ends of the <parameter>string</parameter>
1218        </entry>
1219        <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
1220        <entry><literal>Tom</literal></entry>
1221       </row>
1222
1223       <row>
1224        <entry><literal><function>upper</function>(<parameter>string</parameter>)</literal></entry>
1225        <entry><type>text</type></entry>
1226        <entry>Convert string to uppercase</entry>
1227        <entry><literal>upper('tom')</literal></entry>
1228        <entry><literal>TOM</literal></entry>
1229       </row>
1230      </tbody>
1231     </tgroup>
1232    </table>
1233
1234    <para>
1235     Additional string manipulation functions are available and are
1236     listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
1237     <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
1238    </para>
1239
1240    <indexterm>
1241     <primary>ascii</primary>
1242    </indexterm>
1243    <indexterm>
1244     <primary>btrim</primary>
1245    </indexterm>
1246    <indexterm>
1247     <primary>chr</primary>
1248    </indexterm>
1249    <indexterm>
1250     <primary>convert</primary>
1251    </indexterm>
1252    <indexterm>
1253     <primary>convert_from</primary>
1254    </indexterm>
1255    <indexterm>
1256     <primary>convert_to</primary>
1257    </indexterm>
1258    <indexterm>
1259     <primary>decode</primary>
1260    </indexterm>
1261    <indexterm>
1262     <primary>encode</primary>
1263    </indexterm>
1264    <indexterm>
1265     <primary>initcap</primary>
1266    </indexterm>
1267    <indexterm>
1268     <primary>lpad</primary>
1269    </indexterm>
1270    <indexterm>
1271     <primary>ltrim</primary>
1272    </indexterm>
1273    <indexterm>
1274     <primary>md5</primary>
1275    </indexterm>
1276    <indexterm>
1277     <primary>pg_client_encoding</primary>
1278    </indexterm>
1279    <indexterm>
1280     <primary>quote_ident</primary>
1281    </indexterm>
1282    <indexterm>
1283     <primary>quote_literal</primary>
1284    </indexterm>
1285    <indexterm>
1286     <primary>quote_nullable</primary>
1287    </indexterm>
1288    <indexterm>
1289     <primary>repeat</primary>
1290    </indexterm>
1291    <indexterm>
1292     <primary>replace</primary>
1293    </indexterm>
1294    <indexterm>
1295     <primary>rpad</primary>
1296    </indexterm>
1297    <indexterm>
1298     <primary>rtrim</primary>
1299    </indexterm>
1300    <indexterm>
1301     <primary>split_part</primary>
1302    </indexterm>
1303    <indexterm>
1304     <primary>strpos</primary>
1305    </indexterm>
1306    <indexterm>
1307     <primary>substr</primary>
1308    </indexterm>
1309    <indexterm>
1310     <primary>to_ascii</primary>
1311    </indexterm>
1312    <indexterm>
1313     <primary>to_hex</primary>
1314    </indexterm>
1315    <indexterm>
1316     <primary>translate</primary>
1317    </indexterm>
1318
1319    <table id="functions-string-other">
1320     <title>Other String Functions</title>
1321     <tgroup cols="5">
1322      <thead>
1323       <row>
1324        <entry>Function</entry>
1325        <entry>Return Type</entry>
1326        <entry>Description</entry>
1327        <entry>Example</entry>
1328        <entry>Result</entry>
1329       </row>
1330      </thead>
1331
1332      <tbody>
1333       <row>
1334        <entry><literal><function>ascii</function>(<parameter>string</parameter>)</literal></entry>
1335        <entry><type>int</type></entry>
1336        <entry>
1337         <acronym>ASCII</acronym> code of the first character of the
1338         argument.  For <acronym>UTF8</acronym> returns the Unicode code
1339         point of the character.  For other multibyte encodings, the
1340         argument must be an <acronym>ASCII</acronym> character.
1341        </entry>
1342        <entry><literal>ascii('x')</literal></entry>
1343        <entry><literal>120</literal></entry>
1344       </row>
1345
1346       <row>
1347        <entry><literal><function>btrim</function>(<parameter>string</parameter> <type>text</type>
1348        <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal></entry>
1349        <entry><type>text</type></entry>
1350        <entry>
1351         Remove the longest string consisting only of characters
1352         in <parameter>characters</parameter> (a space by default)
1353         from the start and end of <parameter>string</parameter>
1354        </entry>
1355        <entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
1356        <entry><literal>trim</literal></entry>
1357       </row>
1358
1359       <row>
1360        <entry><literal><function>chr</function>(<type>int</type>)</literal></entry>
1361        <entry><type>text</type></entry>
1362        <entry>
1363         Character with the given code. For <acronym>UTF8</acronym> the
1364         argument is treated as a Unicode code point. For other multibyte
1365         encodings the argument must designate an
1366         <acronym>ASCII</acronym> character.  The NULL (0) character is not
1367         allowed because text data types cannot store such bytes.
1368        </entry>
1369        <entry><literal>chr(65)</literal></entry>
1370        <entry><literal>A</literal></entry>
1371       </row>
1372
1373       <row>
1374        <entry>
1375         <literal><function>convert</function>(<parameter>string</parameter> <type>bytea</type>,
1376         <parameter>src_encoding</parameter> <type>name</type>,
1377         <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1378        </entry>
1379        <entry><type>bytea</type></entry>
1380        <entry>
1381         Convert string to <parameter>dest_encoding</parameter>.  The
1382         original encoding is specified by
1383         <parameter>src_encoding</parameter>. The
1384         <parameter>string</parameter> must be valid in this encoding.
1385         Conversions can be defined by <command>CREATE CONVERSION</command>.  
1386         Also there are some predefined conversions. See <xref
1387         linkend="conversion-names"> for available conversions.
1388        </entry>
1389        <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1390        <entry><literal>text_in_utf8</literal> represented in Latin-1
1391        encoding (ISO 8859-1)</entry>
1392       </row>
1393
1394       <row>
1395        <entry>
1396         <literal><function>convert_from</function>(<parameter>string</parameter> <type>bytea</type>,
1397         <parameter>src_encoding</parameter> <type>name</type>)</literal>
1398        </entry>
1399        <entry><type>text</type></entry>
1400        <entry>
1401         Convert string to the database encoding.  The original encoding
1402         is specified by <parameter>src_encoding</parameter>. The
1403         <parameter>string</parameter> must be valid in this encoding.
1404        </entry>
1405        <entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
1406        <entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
1407       </row>
1408
1409       <row>
1410        <entry>
1411         <literal><function>convert_to</function>(<parameter>string</parameter> <type>text</type>,
1412         <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1413        </entry>
1414        <entry><type>bytea</type></entry>
1415        <entry>
1416         Convert string to <parameter>dest_encoding</parameter>.
1417        </entry>
1418        <entry><literal>convert_to('some text', 'UTF8')</literal></entry>
1419        <entry><literal>some text</literal> represented in the UTF8 encoding</entry>
1420       </row>
1421
1422       <row>
1423        <entry>
1424         <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
1425         <parameter>type</parameter> <type>text</type>)</literal>
1426        </entry>
1427        <entry><type>bytea</type></entry>
1428        <entry>
1429         Decode binary data from <parameter>string</parameter> previously 
1430         encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
1431        </entry>
1432        <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
1433        <entry><literal>123\000\001</literal></entry>
1434       </row>       
1435
1436       <row>
1437        <entry>
1438         <literal><function>encode</function>(<parameter>data</parameter> <type>bytea</type>,
1439         <parameter>type</parameter> <type>text</type>)</literal>
1440        </entry>
1441        <entry><type>text</type></entry>
1442        <entry>
1443         Encode binary data to different representation.  Supported
1444         types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
1445         <literal>Escape</> merely outputs null bytes as <literal>\000</> and
1446         doubles backslashes.
1447        </entry>
1448        <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1449        <entry><literal>MTIzAAE=</literal></entry>
1450       </row>       
1451
1452       <row>
1453        <entry><literal><function>initcap</function>(<parameter>string</parameter>)</literal></entry>
1454        <entry><type>text</type></entry>
1455        <entry>
1456         Convert the first letter of each word to uppercase and the
1457         rest to lowercase. Words are sequences of alphanumeric
1458         characters separated by non-alphanumeric characters.
1459        </entry>
1460        <entry><literal>initcap('hi THOMAS')</literal></entry>
1461        <entry><literal>Hi Thomas</literal></entry>
1462       </row>
1463
1464       <row>
1465        <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
1466        <entry><type>int</type></entry>
1467        <entry>
1468         Number of characters in <parameter>string</parameter>
1469        </entry>
1470        <entry><literal>length('jose')</literal></entry>
1471        <entry><literal>4</literal></entry>
1472       </row>
1473
1474       <row>
1475        <entry><literal><function>length</function>(<parameter>string</parameter><type>bytea</type>,
1476         <parameter>encoding</parameter> <type>name</type> )</literal></entry>
1477        <entry><type>int</type></entry>
1478        <entry>
1479         Number of characters in <parameter>string</parameter> in the given
1480         <parameter>encoding</parameter>. The <parameter>string</parameter>
1481         must be valid in this encoding.
1482        </entry>
1483        <entry><literal>length('jose', 'UTF8')</literal></entry>
1484        <entry><literal>4</literal></entry>
1485       </row>
1486
1487       <row>
1488        <entry>
1489         <literal><function>lpad</function>(<parameter>string</parameter> <type>text</type>,
1490         <parameter>length</parameter> <type>int</type>
1491         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1492        </entry>
1493        <entry><type>text</type></entry>
1494        <entry>
1495         Fill up the <parameter>string</parameter> to length
1496         <parameter>length</parameter> by prepending the characters
1497         <parameter>fill</parameter> (a space by default).  If the
1498         <parameter>string</parameter> is already longer than
1499         <parameter>length</parameter> then it is truncated (on the
1500         right).
1501        </entry>
1502        <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1503        <entry><literal>xyxhi</literal></entry>
1504       </row>
1505
1506       <row>
1507        <entry><literal><function>ltrim</function>(<parameter>string</parameter> <type>text</type>
1508         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
1509        </entry>
1510        <entry><type>text</type></entry>
1511        <entry>
1512         Remove the longest string containing only characters from
1513         <parameter>characters</parameter> (a space by default) from the start of
1514         <parameter>string</parameter>
1515        </entry>
1516        <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
1517        <entry><literal>trim</literal></entry>
1518       </row>
1519
1520       <row>
1521        <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
1522        <entry><type>text</type></entry>
1523        <entry>
1524         Calculates the MD5 hash of <parameter>string</parameter>,
1525         returning the result in hexadecimal
1526        </entry>
1527        <entry><literal>md5('abc')</literal></entry>
1528        <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1529       </row>
1530
1531       <row>
1532        <entry><literal><function>pg_client_encoding</function>()</literal></entry>
1533        <entry><type>name</type></entry>
1534        <entry>
1535         Current client encoding name
1536        </entry>
1537        <entry><literal>pg_client_encoding()</literal></entry>
1538        <entry><literal>SQL_ASCII</literal></entry>
1539       </row>
1540
1541       <row>
1542        <entry><literal><function>quote_ident</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
1543        <entry><type>text</type></entry>
1544        <entry>
1545         Return the given string suitably quoted to be used as an identifier
1546         in an <acronym>SQL</acronym> statement string.
1547         Quotes are added only if necessary (i.e., if the string contains
1548         non-identifier characters or would be case-folded).
1549         Embedded quotes are properly doubled.
1550         See also <xref linkend="plpgsql-quote-literal-example">.
1551        </entry>
1552        <entry><literal>quote_ident('Foo bar')</literal></entry>
1553        <entry><literal>"Foo bar"</literal></entry>
1554       </row>
1555
1556       <row>
1557        <entry><literal><function>quote_literal</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
1558        <entry><type>text</type></entry>
1559        <entry>
1560         Return the given string suitably quoted to be used as a string literal
1561         in an <acronym>SQL</acronym> statement string.
1562         Embedded single-quotes and backslashes are properly doubled.
1563         Note that <function>quote_literal</function> returns null on null
1564         input; if the argument might be null,
1565         <function>quote_nullable</function> is often more suitable.
1566         See also <xref linkend="plpgsql-quote-literal-example">.
1567        </entry>
1568        <entry><literal>quote_literal('O\'Reilly')</literal></entry>
1569        <entry><literal>'O''Reilly'</literal></entry>
1570       </row>
1571
1572       <row>
1573        <entry><literal><function>quote_literal</function>(<parameter>value</parameter> <type>anyelement</type>)</literal></entry>
1574        <entry><type>text</type></entry>
1575        <entry>
1576         Coerce the given value to text and then quote it as a literal.
1577         Embedded single-quotes and backslashes are properly doubled.
1578        </entry>
1579        <entry><literal>quote_literal(42.5)</literal></entry>
1580        <entry><literal>'42.5'</literal></entry>
1581       </row>
1582
1583       <row>
1584        <entry><literal><function>quote_nullable</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
1585        <entry><type>text</type></entry>
1586        <entry>
1587         Return the given string suitably quoted to be used as a string literal
1588         in an <acronym>SQL</acronym> statement string; or, if the argument
1589         is null, return <literal>NULL</>.
1590         Embedded single-quotes and backslashes are properly doubled.
1591         See also <xref linkend="plpgsql-quote-literal-example">.
1592        </entry>
1593        <entry><literal>quote_nullable(NULL)</literal></entry>
1594        <entry><literal>NULL</literal></entry>
1595       </row>
1596
1597       <row>
1598        <entry><literal><function>quote_nullable</function>(<parameter>value</parameter> <type>anyelement</type>)</literal></entry>
1599        <entry><type>text</type></entry>
1600        <entry>
1601         Coerce the given value to text and then quote it as a literal;
1602         or, if the argument is null, return <literal>NULL</>.
1603         Embedded single-quotes and backslashes are properly doubled.
1604        </entry>
1605        <entry><literal>quote_nullable(42.5)</literal></entry>
1606        <entry><literal>'42.5'</literal></entry>
1607       </row>
1608
1609       <row>
1610        <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>
1611        <entry><type>setof text[]</type></entry>
1612        <entry>
1613         Return all captured substrings resulting from matching a POSIX regular
1614         expression against the <parameter>string</parameter>. See
1615         <xref linkend="functions-posix-regexp"> for more information.
1616        </entry>
1617        <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
1618        <entry><literal>{bar,beque}</literal></entry>
1619       </row>
1620
1621       <row>
1622        <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>
1623        <entry><type>text</type></entry>
1624        <entry>
1625         Replace substring(s) matching a POSIX regular expression. See
1626         <xref linkend="functions-posix-regexp"> for more information.
1627        </entry>
1628        <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
1629        <entry><literal>ThM</literal></entry>
1630       </row>
1631
1632       <row>
1633        <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>
1634        <entry><type>text[]</type></entry>
1635        <entry>
1636         Split <parameter>string</parameter> using a POSIX regular expression as
1637         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1638         information.
1639        </entry>
1640        <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
1641        <entry><literal>{hello,world}</literal></entry>
1642       </row>
1643
1644       <row>
1645        <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>
1646        <entry><type>setof text</type></entry>
1647        <entry>
1648         Split <parameter>string</parameter> using a POSIX regular expression as
1649         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
1650         information.
1651        </entry>
1652        <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
1653        <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
1654       </row>
1655
1656       <row>
1657        <entry><literal><function>repeat</function>(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</literal></entry>
1658        <entry><type>text</type></entry>
1659        <entry>Repeat <parameter>string</parameter> the specified
1660        <parameter>number</parameter> of times</entry>
1661        <entry><literal>repeat('Pg', 4)</literal></entry>
1662        <entry><literal>PgPgPgPg</literal></entry>
1663       </row>
1664
1665       <row>
1666        <entry><literal><function>replace</function>(<parameter>string</parameter> <type>text</type>,
1667        <parameter>from</parameter> <type>text</type>,
1668        <parameter>to</parameter> <type>text</type>)</literal></entry>
1669        <entry><type>text</type></entry>
1670        <entry>Replace all occurrences in <parameter>string</parameter> of substring
1671         <parameter>from</parameter> with substring <parameter>to</parameter>
1672        </entry>
1673        <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
1674        <entry><literal>abXXefabXXef</literal></entry>
1675       </row>
1676
1677       <row>
1678        <entry>
1679         <literal><function>rpad</function>(<parameter>string</parameter> <type>text</type>,
1680         <parameter>length</parameter> <type>int</type>
1681         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1682        </entry>
1683        <entry><type>text</type></entry>
1684        <entry>
1685         Fill up the <parameter>string</parameter> to length
1686         <parameter>length</parameter> by appending the characters
1687         <parameter>fill</parameter> (a space by default).  If the
1688         <parameter>string</parameter> is already longer than
1689         <parameter>length</parameter> then it is truncated.
1690        </entry>
1691        <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
1692        <entry><literal>hixyx</literal></entry>
1693       </row>
1694
1695       <row>
1696        <entry><literal><function>rtrim</function>(<parameter>string</parameter> <type>text</type>
1697         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
1698        </entry>
1699        <entry><type>text</type></entry>
1700        <entry>
1701         Remove the longest string containing only characters from
1702         <parameter>characters</parameter> (a space by default) from the end of
1703         <parameter>string</parameter>
1704        </entry>
1705        <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
1706        <entry><literal>trim</literal></entry>
1707       </row>
1708
1709       <row>
1710        <entry><literal><function>split_part</function>(<parameter>string</parameter> <type>text</type>,
1711        <parameter>delimiter</parameter> <type>text</type>,
1712        <parameter>field</parameter> <type>int</type>)</literal></entry>
1713        <entry><type>text</type></entry>
1714        <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1715         and return the given field (counting from one)
1716        </entry>
1717        <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
1718        <entry><literal>def</literal></entry>
1719       </row>
1720
1721       <row>
1722        <entry><literal><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</literal></entry>
1723        <entry><type>int</type></entry>
1724        <entry>
1725         Location of specified substring (same as
1726         <literal>position(<parameter>substring</parameter> in
1727          <parameter>string</parameter>)</literal>, but note the reversed
1728         argument order)
1729        </entry>
1730        <entry><literal>strpos('high', 'ig')</literal></entry>
1731        <entry><literal>2</literal></entry>
1732       </row>
1733
1734       <row>
1735        <entry><literal><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</literal></entry>
1736        <entry><type>text</type></entry>
1737        <entry>
1738         Extract substring (same as
1739         <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
1740        </entry>
1741        <entry><literal>substr('alphabet', 3, 2)</literal></entry>
1742        <entry><literal>ph</literal></entry>
1743       </row>
1744
1745       <row>
1746        <entry><literal><function>to_ascii</function>(<parameter>string</parameter> <type>text</type>
1747         <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</literal></entry>
1748        <entry><type>text</type></entry>
1749
1750        <entry>
1751        Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
1752        (only supports conversion from  <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
1753        and <literal>WIN1250</> encodings)
1754        </entry>
1755
1756        <entry><literal>to_ascii('Karel')</literal></entry>
1757        <entry><literal>Karel</literal></entry>
1758       </row>
1759
1760       <row>
1761        <entry><literal><function>to_hex</function>(<parameter>number</parameter> <type>int</type>
1762        or <type>bigint</type>)</literal></entry>
1763        <entry><type>text</type></entry>
1764        <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
1765         representation
1766        </entry>
1767        <entry><literal>to_hex(2147483647)</literal></entry>
1768        <entry><literal>7fffffff</literal></entry>
1769       </row>
1770
1771       <row>
1772        <entry>
1773         <literal><function>translate</function>(<parameter>string</parameter> <type>text</type>,
1774         <parameter>from</parameter> <type>text</type>,
1775         <parameter>to</parameter> <type>text</type>)</literal>
1776        </entry>
1777        <entry><type>text</type></entry>
1778        <entry>
1779         Any character in <parameter>string</parameter> that matches a
1780         character in the <parameter>from</parameter> set is replaced by
1781         the corresponding character in the <parameter>to</parameter>
1782         set
1783        </entry>
1784        <entry><literal>translate('12345', '14', 'ax')</literal></entry>
1785        <entry><literal>a23x5</literal></entry>
1786       </row>       
1787       
1788      </tbody>
1789     </tgroup>
1790    </table>
1791
1792
1793    <table id="conversion-names">
1794     <title>Built-in Conversions</title>
1795     <tgroup cols="3">
1796      <thead>
1797       <row>
1798        <entry>Conversion Name
1799         <footnote>
1800          <para>
1801           The conversion names follow a standard naming scheme: The
1802           official name of the source encoding with all
1803           non-alphanumeric characters replaced by underscores, followed
1804           by <literal>_to_</literal>, followed by the similarly processed
1805           destination encoding name. Therefore, the names might deviate
1806           from the customary encoding names.
1807          </para>
1808         </footnote>
1809        </entry>
1810        <entry>Source Encoding</entry>
1811        <entry>Destination Encoding</entry>
1812       </row>
1813      </thead>
1814
1815      <tbody>
1816       <row>
1817        <entry><literal>ascii_to_mic</literal></entry>
1818        <entry><literal>SQL_ASCII</literal></entry>
1819        <entry><literal>MULE_INTERNAL</literal></entry>
1820       </row>
1821
1822       <row>
1823        <entry><literal>ascii_to_utf8</literal></entry>
1824        <entry><literal>SQL_ASCII</literal></entry>
1825        <entry><literal>UTF8</literal></entry>
1826       </row>
1827
1828       <row>
1829        <entry><literal>big5_to_euc_tw</literal></entry>
1830        <entry><literal>BIG5</literal></entry>
1831        <entry><literal>EUC_TW</literal></entry>
1832       </row>
1833
1834       <row>
1835        <entry><literal>big5_to_mic</literal></entry>
1836        <entry><literal>BIG5</literal></entry>
1837        <entry><literal>MULE_INTERNAL</literal></entry>
1838       </row>
1839
1840       <row>
1841        <entry><literal>big5_to_utf8</literal></entry>
1842        <entry><literal>BIG5</literal></entry>
1843        <entry><literal>UTF8</literal></entry>
1844       </row>
1845
1846       <row>
1847        <entry><literal>euc_cn_to_mic</literal></entry>
1848        <entry><literal>EUC_CN</literal></entry>
1849        <entry><literal>MULE_INTERNAL</literal></entry>
1850       </row>
1851
1852       <row>
1853        <entry><literal>euc_cn_to_utf8</literal></entry>
1854        <entry><literal>EUC_CN</literal></entry>
1855        <entry><literal>UTF8</literal></entry>
1856       </row>
1857
1858       <row>
1859        <entry><literal>euc_jp_to_mic</literal></entry>
1860        <entry><literal>EUC_JP</literal></entry>
1861        <entry><literal>MULE_INTERNAL</literal></entry>
1862       </row>
1863
1864       <row>
1865        <entry><literal>euc_jp_to_sjis</literal></entry>
1866        <entry><literal>EUC_JP</literal></entry>
1867        <entry><literal>SJIS</literal></entry>
1868       </row>
1869
1870       <row>
1871        <entry><literal>euc_jp_to_utf8</literal></entry>
1872        <entry><literal>EUC_JP</literal></entry>
1873        <entry><literal>UTF8</literal></entry>
1874       </row>
1875
1876       <row>
1877        <entry><literal>euc_kr_to_mic</literal></entry>
1878        <entry><literal>EUC_KR</literal></entry>
1879        <entry><literal>MULE_INTERNAL</literal></entry>
1880       </row>
1881
1882       <row>
1883        <entry><literal>euc_kr_to_utf8</literal></entry>
1884        <entry><literal>EUC_KR</literal></entry>
1885        <entry><literal>UTF8</literal></entry>
1886       </row>
1887
1888       <row>
1889        <entry><literal>euc_tw_to_big5</literal></entry>
1890        <entry><literal>EUC_TW</literal></entry>
1891        <entry><literal>BIG5</literal></entry>
1892       </row>
1893
1894       <row>
1895        <entry><literal>euc_tw_to_mic</literal></entry>
1896        <entry><literal>EUC_TW</literal></entry>
1897        <entry><literal>MULE_INTERNAL</literal></entry>
1898       </row>
1899
1900       <row>
1901        <entry><literal>euc_tw_to_utf8</literal></entry>
1902        <entry><literal>EUC_TW</literal></entry>
1903        <entry><literal>UTF8</literal></entry>
1904       </row>
1905
1906       <row>
1907        <entry><literal>gb18030_to_utf8</literal></entry>
1908        <entry><literal>GB18030</literal></entry>
1909        <entry><literal>UTF8</literal></entry>
1910       </row>
1911
1912       <row>
1913        <entry><literal>gbk_to_utf8</literal></entry>
1914        <entry><literal>GBK</literal></entry>
1915        <entry><literal>UTF8</literal></entry>
1916       </row>
1917
1918       <row>
1919        <entry><literal>iso_8859_10_to_utf8</literal></entry>
1920        <entry><literal>LATIN6</literal></entry>
1921        <entry><literal>UTF8</literal></entry>
1922       </row>
1923
1924       <row>
1925        <entry><literal>iso_8859_13_to_utf8</literal></entry>
1926        <entry><literal>LATIN7</literal></entry>
1927        <entry><literal>UTF8</literal></entry>
1928       </row>
1929
1930       <row>
1931        <entry><literal>iso_8859_14_to_utf8</literal></entry>
1932        <entry><literal>LATIN8</literal></entry>
1933        <entry><literal>UTF8</literal></entry>
1934       </row>
1935
1936       <row>
1937        <entry><literal>iso_8859_15_to_utf8</literal></entry>
1938        <entry><literal>LATIN9</literal></entry>
1939        <entry><literal>UTF8</literal></entry>
1940       </row>
1941
1942       <row>
1943        <entry><literal>iso_8859_16_to_utf8</literal></entry>
1944        <entry><literal>LATIN10</literal></entry>
1945        <entry><literal>UTF8</literal></entry>
1946       </row>
1947
1948       <row>
1949        <entry><literal>iso_8859_1_to_mic</literal></entry>
1950        <entry><literal>LATIN1</literal></entry>
1951        <entry><literal>MULE_INTERNAL</literal></entry>
1952       </row>
1953
1954       <row>
1955        <entry><literal>iso_8859_1_to_utf8</literal></entry>
1956        <entry><literal>LATIN1</literal></entry>
1957        <entry><literal>UTF8</literal></entry>
1958       </row>
1959
1960       <row>
1961        <entry><literal>iso_8859_2_to_mic</literal></entry>
1962        <entry><literal>LATIN2</literal></entry>
1963        <entry><literal>MULE_INTERNAL</literal></entry>
1964       </row>
1965
1966       <row>
1967        <entry><literal>iso_8859_2_to_utf8</literal></entry>
1968        <entry><literal>LATIN2</literal></entry>
1969        <entry><literal>UTF8</literal></entry>
1970       </row>
1971
1972       <row>
1973        <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
1974        <entry><literal>LATIN2</literal></entry>
1975        <entry><literal>WIN1250</literal></entry>
1976       </row>
1977
1978       <row>
1979        <entry><literal>iso_8859_3_to_mic</literal></entry>
1980        <entry><literal>LATIN3</literal></entry>
1981        <entry><literal>MULE_INTERNAL</literal></entry>
1982       </row>
1983
1984       <row>
1985        <entry><literal>iso_8859_3_to_utf8</literal></entry>
1986        <entry><literal>LATIN3</literal></entry>
1987        <entry><literal>UTF8</literal></entry>
1988       </row>
1989
1990       <row>
1991        <entry><literal>iso_8859_4_to_mic</literal></entry>
1992        <entry><literal>LATIN4</literal></entry>
1993        <entry><literal>MULE_INTERNAL</literal></entry>
1994       </row>
1995
1996       <row>
1997        <entry><literal>iso_8859_4_to_utf8</literal></entry>
1998        <entry><literal>LATIN4</literal></entry>
1999        <entry><literal>UTF8</literal></entry>
2000       </row>
2001
2002       <row>
2003        <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
2004        <entry><literal>ISO_8859_5</literal></entry>
2005        <entry><literal>KOI8R</literal></entry>
2006       </row>
2007
2008       <row>
2009        <entry><literal>iso_8859_5_to_mic</literal></entry>
2010        <entry><literal>ISO_8859_5</literal></entry>
2011        <entry><literal>MULE_INTERNAL</literal></entry>
2012       </row>
2013
2014       <row>
2015        <entry><literal>iso_8859_5_to_utf8</literal></entry>
2016        <entry><literal>ISO_8859_5</literal></entry>
2017        <entry><literal>UTF8</literal></entry>
2018       </row>
2019
2020       <row>
2021        <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
2022        <entry><literal>ISO_8859_5</literal></entry>
2023        <entry><literal>WIN1251</literal></entry>
2024       </row>
2025
2026       <row>
2027        <entry><literal>iso_8859_5_to_windows_866</literal></entry>
2028        <entry><literal>ISO_8859_5</literal></entry>
2029        <entry><literal>WIN866</literal></entry>
2030       </row>
2031
2032       <row>
2033        <entry><literal>iso_8859_6_to_utf8</literal></entry>
2034        <entry><literal>ISO_8859_6</literal></entry>
2035        <entry><literal>UTF8</literal></entry>
2036       </row>
2037
2038       <row>
2039        <entry><literal>iso_8859_7_to_utf8</literal></entry>
2040        <entry><literal>ISO_8859_7</literal></entry>
2041        <entry><literal>UTF8</literal></entry>
2042       </row>
2043
2044       <row>
2045        <entry><literal>iso_8859_8_to_utf8</literal></entry>
2046        <entry><literal>ISO_8859_8</literal></entry>
2047        <entry><literal>UTF8</literal></entry>
2048       </row>
2049
2050       <row>
2051        <entry><literal>iso_8859_9_to_utf8</literal></entry>
2052        <entry><literal>LATIN5</literal></entry>
2053        <entry><literal>UTF8</literal></entry>
2054       </row>
2055
2056       <row>
2057        <entry><literal>johab_to_utf8</literal></entry>
2058        <entry><literal>JOHAB</literal></entry>
2059        <entry><literal>UTF8</literal></entry>
2060       </row>
2061
2062       <row>
2063        <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
2064        <entry><literal>KOI8R</literal></entry>
2065        <entry><literal>ISO_8859_5</literal></entry>
2066       </row>
2067
2068       <row>
2069        <entry><literal>koi8_r_to_mic</literal></entry>
2070        <entry><literal>KOI8R</literal></entry>
2071        <entry><literal>MULE_INTERNAL</literal></entry>
2072       </row>
2073
2074       <row>
2075        <entry><literal>koi8_r_to_utf8</literal></entry>
2076        <entry><literal>KOI8R</literal></entry>
2077        <entry><literal>UTF8</literal></entry>
2078       </row>
2079
2080       <row>
2081        <entry><literal>koi8_r_to_windows_1251</literal></entry>
2082        <entry><literal>KOI8R</literal></entry>
2083        <entry><literal>WIN1251</literal></entry>
2084       </row>
2085
2086       <row>
2087        <entry><literal>koi8_r_to_windows_866</literal></entry>
2088        <entry><literal>KOI8R</literal></entry>
2089        <entry><literal>WIN866</literal></entry>
2090       </row>
2091
2092       <row>
2093        <entry><literal>koi8_u_to_utf8</literal></entry>
2094        <entry><literal>KOI8U</literal></entry>
2095        <entry><literal>UTF8</literal></entry>
2096       </row>
2097
2098       <row>
2099        <entry><literal>mic_to_ascii</literal></entry>
2100        <entry><literal>MULE_INTERNAL</literal></entry>
2101        <entry><literal>SQL_ASCII</literal></entry>
2102       </row>
2103
2104       <row>
2105        <entry><literal>mic_to_big5</literal></entry>
2106        <entry><literal>MULE_INTERNAL</literal></entry>
2107        <entry><literal>BIG5</literal></entry>
2108       </row>
2109
2110       <row>
2111        <entry><literal>mic_to_euc_cn</literal></entry>
2112        <entry><literal>MULE_INTERNAL</literal></entry>
2113        <entry><literal>EUC_CN</literal></entry>
2114       </row>
2115
2116       <row>
2117        <entry><literal>mic_to_euc_jp</literal></entry>
2118        <entry><literal>MULE_INTERNAL</literal></entry>
2119        <entry><literal>EUC_JP</literal></entry>
2120       </row>
2121
2122       <row>
2123        <entry><literal>mic_to_euc_kr</literal></entry>
2124        <entry><literal>MULE_INTERNAL</literal></entry>
2125        <entry><literal>EUC_KR</literal></entry>
2126       </row>
2127
2128       <row>
2129        <entry><literal>mic_to_euc_tw</literal></entry>
2130        <entry><literal>MULE_INTERNAL</literal></entry>
2131        <entry><literal>EUC_TW</literal></entry>
2132       </row>
2133
2134       <row>
2135        <entry><literal>mic_to_iso_8859_1</literal></entry>
2136        <entry><literal>MULE_INTERNAL</literal></entry>
2137        <entry><literal>LATIN1</literal></entry>
2138       </row>
2139
2140       <row>
2141        <entry><literal>mic_to_iso_8859_2</literal></entry>
2142        <entry><literal>MULE_INTERNAL</literal></entry>
2143        <entry><literal>LATIN2</literal></entry>
2144       </row>
2145
2146       <row>
2147        <entry><literal>mic_to_iso_8859_3</literal></entry>
2148        <entry><literal>MULE_INTERNAL</literal></entry>
2149        <entry><literal>LATIN3</literal></entry>
2150       </row>
2151
2152       <row>
2153        <entry><literal>mic_to_iso_8859_4</literal></entry>
2154        <entry><literal>MULE_INTERNAL</literal></entry>
2155        <entry><literal>LATIN4</literal></entry>
2156       </row>
2157
2158       <row>
2159        <entry><literal>mic_to_iso_8859_5</literal></entry>
2160        <entry><literal>MULE_INTERNAL</literal></entry>
2161        <entry><literal>ISO_8859_5</literal></entry>
2162       </row>
2163
2164       <row>
2165        <entry><literal>mic_to_koi8_r</literal></entry>
2166        <entry><literal>MULE_INTERNAL</literal></entry>
2167        <entry><literal>KOI8R</literal></entry>
2168       </row>
2169
2170       <row>
2171        <entry><literal>mic_to_sjis</literal></entry>
2172        <entry><literal>MULE_INTERNAL</literal></entry>
2173        <entry><literal>SJIS</literal></entry>
2174       </row>
2175
2176       <row>
2177        <entry><literal>mic_to_windows_1250</literal></entry>
2178        <entry><literal>MULE_INTERNAL</literal></entry>
2179        <entry><literal>WIN1250</literal></entry>
2180       </row>
2181
2182       <row>
2183        <entry><literal>mic_to_windows_1251</literal></entry>
2184        <entry><literal>MULE_INTERNAL</literal></entry>
2185        <entry><literal>WIN1251</literal></entry>
2186       </row>
2187
2188       <row>
2189        <entry><literal>mic_to_windows_866</literal></entry>
2190        <entry><literal>MULE_INTERNAL</literal></entry>
2191        <entry><literal>WIN866</literal></entry>
2192       </row>
2193
2194       <row>
2195        <entry><literal>sjis_to_euc_jp</literal></entry>
2196        <entry><literal>SJIS</literal></entry>
2197        <entry><literal>EUC_JP</literal></entry>
2198       </row>
2199
2200       <row>
2201        <entry><literal>sjis_to_mic</literal></entry>
2202        <entry><literal>SJIS</literal></entry>
2203        <entry><literal>MULE_INTERNAL</literal></entry>
2204       </row>
2205
2206       <row>
2207        <entry><literal>sjis_to_utf8</literal></entry>
2208        <entry><literal>SJIS</literal></entry>
2209        <entry><literal>UTF8</literal></entry>
2210       </row>
2211
2212       <row>
2213        <entry><literal>tcvn_to_utf8</literal></entry>
2214        <entry><literal>WIN1258</literal></entry>
2215        <entry><literal>UTF8</literal></entry>
2216       </row>
2217
2218       <row>
2219        <entry><literal>uhc_to_utf8</literal></entry>
2220        <entry><literal>UHC</literal></entry>
2221        <entry><literal>UTF8</literal></entry>
2222       </row>
2223
2224       <row>
2225        <entry><literal>utf8_to_ascii</literal></entry>
2226        <entry><literal>UTF8</literal></entry>
2227        <entry><literal>SQL_ASCII</literal></entry>
2228       </row>
2229
2230       <row>
2231        <entry><literal>utf8_to_big5</literal></entry>
2232        <entry><literal>UTF8</literal></entry>
2233        <entry><literal>BIG5</literal></entry>
2234       </row>
2235
2236       <row>
2237        <entry><literal>utf8_to_euc_cn</literal></entry>
2238        <entry><literal>UTF8</literal></entry>
2239        <entry><literal>EUC_CN</literal></entry>
2240       </row>
2241
2242       <row>
2243        <entry><literal>utf8_to_euc_jp</literal></entry>
2244        <entry><literal>UTF8</literal></entry>
2245        <entry><literal>EUC_JP</literal></entry>
2246       </row>
2247
2248       <row>
2249        <entry><literal>utf8_to_euc_kr</literal></entry>
2250        <entry><literal>UTF8</literal></entry>
2251        <entry><literal>EUC_KR</literal></entry>
2252       </row>
2253
2254       <row>
2255        <entry><literal>utf8_to_euc_tw</literal></entry>
2256        <entry><literal>UTF8</literal></entry>
2257        <entry><literal>EUC_TW</literal></entry>
2258       </row>
2259
2260       <row>
2261        <entry><literal>utf8_to_gb18030</literal></entry>
2262        <entry><literal>UTF8</literal></entry>
2263        <entry><literal>GB18030</literal></entry>
2264       </row>
2265
2266       <row>
2267        <entry><literal>utf8_to_gbk</literal></entry>
2268        <entry><literal>UTF8</literal></entry>
2269        <entry><literal>GBK</literal></entry>
2270       </row>
2271
2272       <row>
2273        <entry><literal>utf8_to_iso_8859_1</literal></entry>
2274        <entry><literal>UTF8</literal></entry>
2275        <entry><literal>LATIN1</literal></entry>
2276       </row>
2277
2278       <row>
2279        <entry><literal>utf8_to_iso_8859_10</literal></entry>
2280        <entry><literal>UTF8</literal></entry>
2281        <entry><literal>LATIN6</literal></entry>
2282       </row>
2283
2284       <row>
2285        <entry><literal>utf8_to_iso_8859_13</literal></entry>
2286        <entry><literal>UTF8</literal></entry>
2287        <entry><literal>LATIN7</literal></entry>
2288       </row>
2289
2290       <row>
2291        <entry><literal>utf8_to_iso_8859_14</literal></entry>
2292        <entry><literal>UTF8</literal></entry>
2293        <entry><literal>LATIN8</literal></entry>
2294       </row>
2295
2296       <row>
2297        <entry><literal>utf8_to_iso_8859_15</literal></entry>
2298        <entry><literal>UTF8</literal></entry>
2299        <entry><literal>LATIN9</literal></entry>
2300       </row>
2301
2302       <row>
2303        <entry><literal>utf8_to_iso_8859_16</literal></entry>
2304        <entry><literal>UTF8</literal></entry>
2305        <entry><literal>LATIN10</literal></entry>
2306       </row>
2307
2308       <row>
2309        <entry><literal>utf8_to_iso_8859_2</literal></entry>
2310        <entry><literal>UTF8</literal></entry>
2311        <entry><literal>LATIN2</literal></entry>
2312       </row>
2313
2314       <row>
2315        <entry><literal>utf8_to_iso_8859_3</literal></entry>
2316        <entry><literal>UTF8</literal></entry>
2317        <entry><literal>LATIN3</literal></entry>
2318       </row>
2319
2320       <row>
2321        <entry><literal>utf8_to_iso_8859_4</literal></entry>
2322        <entry><literal>UTF8</literal></entry>
2323        <entry><literal>LATIN4</literal></entry>
2324       </row>
2325
2326       <row>
2327        <entry><literal>utf8_to_iso_8859_5</literal></entry>
2328        <entry><literal>UTF8</literal></entry>
2329        <entry><literal>ISO_8859_5</literal></entry>
2330       </row>
2331
2332       <row>
2333        <entry><literal>utf8_to_iso_8859_6</literal></entry>
2334        <entry><literal>UTF8</literal></entry>
2335        <entry><literal>ISO_8859_6</literal></entry>
2336       </row>
2337
2338       <row>
2339        <entry><literal>utf8_to_iso_8859_7</literal></entry>
2340        <entry><literal>UTF8</literal></entry>
2341        <entry><literal>ISO_8859_7</literal></entry>
2342       </row>
2343
2344       <row>
2345        <entry><literal>utf8_to_iso_8859_8</literal></entry>
2346        <entry><literal>UTF8</literal></entry>
2347        <entry><literal>ISO_8859_8</literal></entry>
2348       </row>
2349
2350       <row>
2351        <entry><literal>utf8_to_iso_8859_9</literal></entry>
2352        <entry><literal>UTF8</literal></entry>
2353        <entry><literal>LATIN5</literal></entry>
2354       </row>
2355
2356       <row>
2357        <entry><literal>utf8_to_johab</literal></entry>
2358        <entry><literal>UTF8</literal></entry>
2359        <entry><literal>JOHAB</literal></entry>
2360       </row>
2361
2362       <row>
2363        <entry><literal>utf8_to_koi8_r</literal></entry>
2364        <entry><literal>UTF8</literal></entry>
2365        <entry><literal>KOI8R</literal></entry>
2366       </row>
2367
2368       <row>
2369        <entry><literal>utf8_to_koi8_u</literal></entry>
2370        <entry><literal>UTF8</literal></entry>
2371        <entry><literal>KOI8U</literal></entry>
2372       </row>
2373
2374       <row>
2375        <entry><literal>utf8_to_sjis</literal></entry>
2376        <entry><literal>UTF8</literal></entry>
2377        <entry><literal>SJIS</literal></entry>
2378       </row>
2379
2380       <row>
2381        <entry><literal>utf8_to_tcvn</literal></entry>
2382        <entry><literal>UTF8</literal></entry>
2383        <entry><literal>WIN1258</literal></entry>
2384       </row>
2385
2386       <row>
2387        <entry><literal>utf8_to_uhc</literal></entry>
2388        <entry><literal>UTF8</literal></entry>
2389        <entry><literal>UHC</literal></entry>
2390       </row>
2391
2392       <row>
2393        <entry><literal>utf8_to_windows_1250</literal></entry>
2394        <entry><literal>UTF8</literal></entry>
2395        <entry><literal>WIN1250</literal></entry>
2396       </row>
2397
2398       <row>
2399        <entry><literal>utf8_to_windows_1251</literal></entry>
2400        <entry><literal>UTF8</literal></entry>
2401        <entry><literal>WIN1251</literal></entry>
2402       </row>
2403
2404       <row>
2405        <entry><literal>utf8_to_windows_1252</literal></entry>
2406        <entry><literal>UTF8</literal></entry>
2407        <entry><literal>WIN1252</literal></entry>
2408       </row>
2409
2410       <row>
2411        <entry><literal>utf8_to_windows_1253</literal></entry>
2412        <entry><literal>UTF8</literal></entry>
2413        <entry><literal>WIN1253</literal></entry>
2414       </row>
2415
2416       <row>
2417        <entry><literal>utf8_to_windows_1254</literal></entry>
2418        <entry><literal>UTF8</literal></entry>
2419        <entry><literal>WIN1254</literal></entry>
2420       </row>
2421
2422       <row>
2423        <entry><literal>utf8_to_windows_1255</literal></entry>
2424        <entry><literal>UTF8</literal></entry>
2425        <entry><literal>WIN1255</literal></entry>
2426       </row>
2427
2428       <row>
2429        <entry><literal>utf8_to_windows_1256</literal></entry>
2430        <entry><literal>UTF8</literal></entry>
2431        <entry><literal>WIN1256</literal></entry>
2432       </row>
2433
2434       <row>
2435        <entry><literal>utf8_to_windows_1257</literal></entry>
2436        <entry><literal>UTF8</literal></entry>
2437        <entry><literal>WIN1257</literal></entry>
2438       </row>
2439
2440       <row>
2441        <entry><literal>utf8_to_windows_866</literal></entry>
2442        <entry><literal>UTF8</literal></entry>
2443        <entry><literal>WIN866</literal></entry>
2444       </row>
2445
2446       <row>
2447        <entry><literal>utf8_to_windows_874</literal></entry>
2448        <entry><literal>UTF8</literal></entry>
2449        <entry><literal>WIN874</literal></entry>
2450       </row>
2451
2452       <row>
2453        <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
2454        <entry><literal>WIN1250</literal></entry>
2455        <entry><literal>LATIN2</literal></entry>
2456       </row>
2457
2458       <row>
2459        <entry><literal>windows_1250_to_mic</literal></entry>
2460        <entry><literal>WIN1250</literal></entry>
2461        <entry><literal>MULE_INTERNAL</literal></entry>
2462       </row>
2463
2464       <row>
2465        <entry><literal>windows_1250_to_utf8</literal></entry>
2466        <entry><literal>WIN1250</literal></entry>
2467        <entry><literal>UTF8</literal></entry>
2468       </row>
2469
2470       <row>
2471        <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
2472        <entry><literal>WIN1251</literal></entry>
2473        <entry><literal>ISO_8859_5</literal></entry>
2474       </row>
2475
2476       <row>
2477        <entry><literal>windows_1251_to_koi8_r</literal></entry>
2478        <entry><literal>WIN1251</literal></entry>
2479        <entry><literal>KOI8R</literal></entry>
2480       </row>
2481
2482       <row>
2483        <entry><literal>windows_1251_to_mic</literal></entry>
2484        <entry><literal>WIN1251</literal></entry>
2485        <entry><literal>MULE_INTERNAL</literal></entry>
2486       </row>
2487
2488       <row>
2489        <entry><literal>windows_1251_to_utf8</literal></entry>
2490        <entry><literal>WIN1251</literal></entry>
2491        <entry><literal>UTF8</literal></entry>
2492       </row>
2493
2494       <row>
2495        <entry><literal>windows_1251_to_windows_866</literal></entry>
2496        <entry><literal>WIN1251</literal></entry>
2497        <entry><literal>WIN866</literal></entry>
2498       </row>
2499
2500       <row>
2501        <entry><literal>windows_1252_to_utf8</literal></entry>
2502        <entry><literal>WIN1252</literal></entry>
2503        <entry><literal>UTF8</literal></entry>
2504       </row>
2505
2506       <row>
2507        <entry><literal>windows_1256_to_utf8</literal></entry>
2508        <entry><literal>WIN1256</literal></entry>
2509        <entry><literal>UTF8</literal></entry>
2510       </row>
2511
2512       <row>
2513        <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2514        <entry><literal>WIN866</literal></entry>
2515        <entry><literal>ISO_8859_5</literal></entry>
2516       </row>
2517
2518       <row>
2519        <entry><literal>windows_866_to_koi8_r</literal></entry>
2520        <entry><literal>WIN866</literal></entry>
2521        <entry><literal>KOI8R</literal></entry>
2522       </row>
2523
2524       <row>
2525        <entry><literal>windows_866_to_mic</literal></entry>
2526        <entry><literal>WIN866</literal></entry>
2527        <entry><literal>MULE_INTERNAL</literal></entry>
2528       </row>
2529
2530       <row>
2531        <entry><literal>windows_866_to_utf8</literal></entry>
2532        <entry><literal>WIN866</literal></entry>
2533        <entry><literal>UTF8</literal></entry>
2534       </row>
2535
2536       <row>
2537        <entry><literal>windows_866_to_windows_1251</literal></entry>
2538        <entry><literal>WIN866</literal></entry>
2539        <entry><literal>WIN</literal></entry>
2540       </row>
2541
2542       <row>
2543        <entry><literal>windows_874_to_utf8</literal></entry>
2544        <entry><literal>WIN874</literal></entry>
2545        <entry><literal>UTF8</literal></entry>
2546       </row>
2547
2548       <row>
2549        <entry><literal>euc_jis_2004_to_utf8</literal></entry>
2550        <entry><literal>EUC_JIS_2004</literal></entry>
2551        <entry><literal>UTF8</literal></entry>
2552       </row>
2553
2554       <row>
2555        <entry><literal>ut8_to_euc_jis_2004</literal></entry>
2556        <entry><literal>UTF8</literal></entry>
2557        <entry><literal>EUC_JIS_2004</literal></entry>
2558       </row>
2559
2560       <row>
2561        <entry><literal>shift_jis_2004_to_utf8</literal></entry>
2562        <entry><literal>SHIFT_JIS_2004</literal></entry>
2563        <entry><literal>UTF8</literal></entry>
2564       </row>
2565
2566       <row>
2567        <entry><literal>ut8_to_shift_jis_2004</literal></entry>
2568        <entry><literal>UTF8</literal></entry>
2569        <entry><literal>SHIFT_JIS_2004</literal></entry>
2570       </row>
2571
2572       <row>
2573        <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
2574        <entry><literal>EUC_JIS_2004</literal></entry>
2575        <entry><literal>SHIFT_JIS_2004</literal></entry>
2576       </row>
2577
2578       <row>
2579        <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
2580        <entry><literal>SHIFT_JIS_2004</literal></entry>
2581        <entry><literal>EUC_JIS_2004</literal></entry>
2582       </row>
2583
2584      </tbody>
2585     </tgroup>
2586    </table>
2587
2588   </sect1>
2589
2590
2591   <sect1 id="functions-binarystring">
2592    <title>Binary String Functions and Operators</title>
2593
2594    <indexterm zone="functions-binarystring">
2595     <primary>binary data</primary>
2596     <secondary>functions</secondary>
2597    </indexterm>
2598
2599    <para>
2600     This section describes functions and operators for examining and
2601     manipulating values of type <type>bytea</type>.
2602    </para>
2603
2604    <para>
2605     <acronym>SQL</acronym> defines some string functions that use
2606     key words, rather than commas, to separate
2607     arguments.  Details are in
2608     <xref linkend="functions-binarystring-sql">.
2609     <productname>PostgreSQL</> also provides versions of these functions
2610     that use the regular function invocation syntax
2611     (see <xref linkend="functions-binarystring-other">).
2612    </para>
2613
2614    <table id="functions-binarystring-sql">
2615     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
2616     <tgroup cols="5">
2617      <thead>
2618       <row>
2619        <entry>Function</entry>
2620        <entry>Return Type</entry>
2621        <entry>Description</entry>
2622        <entry>Example</entry>
2623        <entry>Result</entry>  
2624       </row>
2625      </thead>
2626
2627      <tbody>
2628       <row>
2629        <entry><literal><parameter>string</parameter> <literal>||</literal>
2630         <parameter>string</parameter></literal></entry>
2631        <entry> <type>bytea</type> </entry>
2632        <entry>
2633         String concatenation
2634         <indexterm>
2635          <primary>binary string</primary>
2636          <secondary>concatenation</secondary>
2637         </indexterm>
2638        </entry>
2639        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
2640        <entry><literal>\\Post'gres\000</literal></entry>
2641       </row>
2642
2643       <row>
2644        <entry><function>get_bit</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2645        <entry><type>int</type></entry>
2646        <entry>
2647         Extract bit from string
2648         <indexterm>
2649          <primary>get_bit</primary>
2650         </indexterm>
2651        </entry>
2652        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
2653        <entry><literal>1</literal></entry>
2654       </row>
2655
2656       <row>
2657        <entry><function>get_byte</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2658        <entry><type>int</type></entry>
2659        <entry>
2660         Extract byte from string
2661         <indexterm>
2662          <primary>get_byte</primary>
2663         </indexterm>
2664        </entry>
2665        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
2666        <entry><literal>109</literal></entry>
2667       </row>
2668
2669       <row>
2670        <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
2671        <entry><type>int</type></entry>
2672        <entry>Number of bytes in binary string</entry>
2673        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
2674        <entry><literal>5</literal></entry>
2675       </row>
2676
2677       <row>
2678        <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
2679        <entry><type>int</type></entry>
2680        <entry>Location of specified substring</entry>
2681       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
2682        <entry><literal>3</literal></entry>
2683       </row>
2684
2685       <row>
2686        <entry><function>set_bit</function>(<parameter>string</parameter>,
2687        <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2688        <entry><type>bytea</type></entry>
2689        <entry>
2690         Set bit in string
2691         <indexterm>
2692          <primary>set_bit</primary>
2693         </indexterm>
2694        </entry>
2695        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
2696        <entry><literal>Th\000omAs</literal></entry>
2697       </row>
2698
2699       <row>
2700        <entry><function>set_byte</function>(<parameter>string</parameter>,
2701        <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2702        <entry><type>bytea</type></entry>
2703        <entry>
2704         Set byte in string
2705         <indexterm>
2706          <primary>set_byte</primary>
2707         </indexterm>
2708        </entry>
2709        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
2710        <entry><literal>Th\000o@as</literal></entry>
2711       </row>
2712
2713       <row>
2714        <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
2715        <entry><type>bytea</type></entry>
2716        <entry>
2717         Extract substring
2718         <indexterm>
2719          <primary>substring</primary>
2720         </indexterm>
2721        </entry>
2722        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
2723        <entry><literal>h\000o</literal></entry>
2724       </row>
2725
2726       <row>
2727        <entry>
2728         <literal><function>trim</function>(<optional>both</optional>
2729         <parameter>bytes</parameter> from
2730         <parameter>string</parameter>)</literal>
2731        </entry>
2732        <entry><type>bytea</type></entry>
2733        <entry>
2734         Remove the longest string containing only the bytes in
2735         <parameter>bytes</parameter> from the start
2736         and end of <parameter>string</parameter>
2737        </entry>
2738        <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
2739        <entry><literal>Tom</literal></entry>
2740       </row>
2741      </tbody>
2742     </tgroup>
2743    </table>
2744
2745    <para>
2746     Additional binary string manipulation functions are available and
2747     are listed in <xref linkend="functions-binarystring-other">.  Some
2748     of them are used internally to implement the
2749     <acronym>SQL</acronym>-standard string functions listed in <xref
2750     linkend="functions-binarystring-sql">.
2751    </para>
2752
2753    <table id="functions-binarystring-other">
2754     <title>Other Binary String Functions</title>
2755     <tgroup cols="5">
2756      <thead>
2757       <row>
2758        <entry>Function</entry>
2759        <entry>Return Type</entry>
2760        <entry>Description</entry>
2761        <entry>Example</entry>
2762        <entry>Result</entry>
2763       </row>
2764      </thead>
2765
2766      <tbody>
2767       <row>
2768        <entry><literal><function>btrim</function>(<parameter>string</parameter>
2769         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</literal></entry>
2770        <entry><type>bytea</type></entry>
2771        <entry>
2772         Remove the longest string consisting only of bytes
2773         in <parameter>bytes</parameter> from the start and end of
2774         <parameter>string</parameter>
2775       </entry>
2776       <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
2777       <entry><literal>trim</literal></entry>
2778      </row>
2779
2780      <row>
2781       <entry>
2782        <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
2783               <parameter>type</parameter> <type>text</type>)</literal>
2784       </entry>
2785       <entry><type>bytea</type></entry>
2786       <entry>
2787        Decode binary string from <parameter>string</parameter> previously 
2788        encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
2789       </entry>
2790       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
2791       <entry><literal>123\000456</literal></entry>
2792      </row>
2793
2794      <row>
2795       <entry>
2796        <literal><function>encode</function>(<parameter>string</parameter> <type>bytea</type>,
2797               <parameter>type</parameter> <type>text</type>)</literal>
2798       </entry>
2799       <entry><type>text</type></entry>
2800       <entry>
2801        Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
2802        types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
2803       </entry>
2804       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
2805       <entry><literal>123\000456</literal></entry>
2806      </row>
2807
2808      <row>
2809       <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
2810       <entry><type>int</type></entry>
2811       <entry>
2812        Length of binary string
2813        <indexterm>
2814         <primary>binary string</primary>
2815         <secondary>length</secondary>
2816        </indexterm>
2817        <indexterm>
2818         <primary>length</primary>
2819         <secondary sortas="binary string">of a binary string</secondary>
2820         <see>binary strings, length</see>
2821        </indexterm>
2822       </entry>
2823       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
2824       <entry><literal>5</literal></entry>
2825      </row>
2826
2827      <row>
2828       <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
2829       <entry><type>text</type></entry>
2830       <entry>
2831        Calculates the MD5 hash of <parameter>string</parameter>,
2832        returning the result in hexadecimal
2833       </entry>
2834       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
2835       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
2836      </row>
2837     </tbody>
2838    </tgroup>
2839   </table>
2840
2841  </sect1>
2842
2843
2844   <sect1 id="functions-bitstring">
2845    <title>Bit String Functions and Operators</title>
2846
2847    <indexterm zone="functions-bitstring">
2848     <primary>bit strings</primary>
2849     <secondary>functions</secondary>
2850    </indexterm>
2851
2852    <para>
2853     This section describes functions and operators for examining and
2854     manipulating bit strings, that is values of the types
2855     <type>bit</type> and <type>bit varying</type>.  Aside from the
2856     usual comparison operators, the operators
2857     shown in <xref linkend="functions-bit-string-op-table"> can be used.
2858     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
2859     and <literal>#</literal> must be of equal length.  When bit
2860     shifting, the original length of the string is preserved, as shown
2861     in the examples.
2862    </para>
2863
2864    <table id="functions-bit-string-op-table">
2865     <title>Bit String Operators</title>
2866
2867     <tgroup cols="4">
2868      <thead>
2869       <row>
2870        <entry>Operator</entry>
2871        <entry>Description</entry>
2872        <entry>Example</entry>
2873        <entry>Result</entry>
2874       </row>
2875      </thead>
2876
2877      <tbody>
2878       <row>
2879        <entry> <literal>||</literal> </entry>
2880        <entry>concatenation</entry>
2881        <entry><literal>B'10001' || B'011'</literal></entry>
2882        <entry><literal>10001011</literal></entry>
2883       </row>
2884
2885       <row>
2886        <entry> <literal>&amp;</literal> </entry>
2887        <entry>bitwise AND</entry>
2888        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
2889        <entry><literal>00001</literal></entry>
2890       </row>
2891
2892       <row>
2893        <entry> <literal>|</literal> </entry>
2894        <entry>bitwise OR</entry>
2895        <entry><literal>B'10001' | B'01101'</literal></entry>
2896        <entry><literal>11101</literal></entry>
2897       </row>
2898
2899       <row>
2900        <entry> <literal>#</literal> </entry>
2901        <entry>bitwise XOR</entry>
2902        <entry><literal>B'10001' # B'01101'</literal></entry>
2903        <entry><literal>11100</literal></entry>
2904       </row>
2905
2906       <row>
2907        <entry> <literal>~</literal> </entry>
2908        <entry>bitwise NOT</entry>
2909        <entry><literal>~ B'10001'</literal></entry>
2910        <entry><literal>01110</literal></entry>
2911       </row>
2912
2913       <row>
2914        <entry> <literal>&lt;&lt;</literal> </entry>
2915        <entry>bitwise shift left</entry>
2916        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
2917        <entry><literal>01000</literal></entry>
2918       </row>
2919
2920       <row>
2921        <entry> <literal>&gt;&gt;</literal> </entry>
2922        <entry>bitwise shift right</entry>
2923        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
2924        <entry><literal>00100</literal></entry>
2925       </row>
2926      </tbody>
2927     </tgroup>
2928    </table>
2929
2930    <para>
2931     The following <acronym>SQL</acronym>-standard functions work on bit
2932     strings as well as character strings:
2933     <literal><function>length</function></literal>,
2934     <literal><function>bit_length</function></literal>,
2935     <literal><function>octet_length</function></literal>,
2936     <literal><function>position</function></literal>,
2937     <literal><function>substring</function></literal>.
2938    </para>
2939
2940    <para>
2941     In addition, it is possible to cast integral values to and from type
2942     <type>bit</>.
2943     Some examples:
2944 <programlisting>
2945 44::bit(10)                    <lineannotation>0000101100</lineannotation>
2946 44::bit(3)                     <lineannotation>100</lineannotation>
2947 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
2948 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
2949 </programlisting>
2950     Note that casting to just <quote>bit</> means casting to
2951     <literal>bit(1)</>, and so will deliver only the least significant
2952     bit of the integer.
2953    </para>
2954
2955     <note>
2956      <para>
2957       Prior to <productname>PostgreSQL</productname> 8.0, casting an
2958       integer to <type>bit(n)</> would copy the leftmost <literal>n</>
2959       bits of the integer, whereas now it copies the rightmost <literal>n</>
2960       bits.  Also, casting an integer to a bit string width wider than
2961       the integer itself will sign-extend on the left.
2962      </para>
2963     </note>
2964
2965   </sect1>
2966
2967
2968  <sect1 id="functions-matching">
2969   <title>Pattern Matching</title>
2970
2971   <indexterm zone="functions-matching">
2972    <primary>pattern matching</primary>
2973   </indexterm>
2974
2975    <para>
2976     There are three separate approaches to pattern matching provided
2977     by <productname>PostgreSQL</productname>: the traditional
2978     <acronym>SQL</acronym> <function>LIKE</function> operator, the
2979     more recent <function>SIMILAR TO</function> operator (added in
2980     SQL:1999), and <acronym>POSIX</acronym>-style regular
2981     expressions.  Aside from the basic <quote>does this string match
2982     this pattern?</> operators, functions are available to extract
2983     or replace matching substrings and to split a string at matching
2984     locations.
2985    </para>
2986
2987    <tip>
2988     <para>
2989      If you have pattern matching needs that go beyond this,
2990      consider writing a user-defined function in Perl or Tcl.
2991     </para>
2992    </tip>
2993
2994   <sect2 id="functions-like">
2995    <title><function>LIKE</function></title>
2996
2997    <indexterm>
2998     <primary>LIKE</primary>
2999    </indexterm>
3000
3001 <synopsis>
3002 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3003 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3004 </synopsis>
3005
3006     <para>
3007      The <function>LIKE</function> expression returns true if the
3008      <replaceable>string</replaceable> matches the supplied
3009      <replaceable>pattern</replaceable>.  (As
3010      expected, the <function>NOT LIKE</function> expression returns
3011      false if <function>LIKE</function> returns true, and vice versa.
3012      An equivalent expression is
3013      <literal>NOT (<replaceable>string</replaceable> LIKE
3014       <replaceable>pattern</replaceable>)</literal>.)
3015     </para>
3016
3017     <para>
3018      If <replaceable>pattern</replaceable> does not contain percent
3019      signs or underscores, then the pattern only represents the string
3020      itself; in that case <function>LIKE</function> acts like the
3021      equals operator.  An underscore (<literal>_</literal>) in
3022      <replaceable>pattern</replaceable> stands for (matches) any single
3023      character; a percent sign (<literal>%</literal>) matches any sequence
3024      of zero or more characters.
3025     </para>
3026
3027    <para>
3028     Some examples:
3029 <programlisting>
3030 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
3031 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
3032 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
3033 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
3034 </programlisting>
3035    </para>
3036
3037    <para>
3038     <function>LIKE</function> pattern matching always covers the entire
3039     string.  Therefore, to match a sequence anywhere within a string, the
3040     pattern must start and end with a percent sign.
3041    </para>
3042
3043    <para>
3044     To match a literal underscore or percent sign without matching
3045     other characters, the respective character in
3046     <replaceable>pattern</replaceable> must be
3047     preceded by the escape character.  The default escape
3048     character is the backslash but a different one can be selected by
3049     using the <literal>ESCAPE</literal> clause.  To match the escape
3050     character itself, write two escape characters.
3051    </para>
3052
3053    <para>
3054     Note that the backslash already has a special meaning in string literals,
3055     so to write a pattern constant that contains a backslash you must write two
3056     backslashes in an SQL statement (assuming escape string syntax is used, see
3057     <xref linkend="sql-syntax-strings">).  Thus, writing a pattern that
3058     actually matches a literal backslash means writing four backslashes in the
3059     statement.  You can avoid this by selecting a different escape character
3060     with <literal>ESCAPE</literal>; then a backslash is not special to
3061     <function>LIKE</function> anymore. (But backslash is still special to the
3062     string literal parser, so you still need two of them to match a backslash.)
3063    </para>
3064
3065    <para>
3066     It's also possible to select no escape character by writing
3067     <literal>ESCAPE ''</literal>.  This effectively disables the
3068     escape mechanism, which makes it impossible to turn off the
3069     special meaning of underscore and percent signs in the pattern.
3070    </para>
3071
3072    <para>
3073     The key word <token>ILIKE</token> can be used instead of
3074     <token>LIKE</token> to make the match case-insensitive according
3075     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3076     <productname>PostgreSQL</productname> extension.
3077    </para>
3078
3079    <para>
3080     The operator <literal>~~</literal> is equivalent to
3081     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3082     <function>ILIKE</function>.  There are also
3083     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3084     represent <function>NOT LIKE</function> and <function>NOT
3085     ILIKE</function>, respectively.  All of these operators are
3086     <productname>PostgreSQL</productname>-specific.
3087    </para>
3088   </sect2>
3089
3090
3091   <sect2 id="functions-similarto-regexp">
3092    <title><function>SIMILAR TO</function> Regular Expressions</title>
3093
3094    <indexterm>
3095     <primary>regular expression</primary>
3096     <!-- <seealso>pattern matching</seealso> breaks index build -->
3097    </indexterm>
3098
3099    <indexterm>
3100     <primary>SIMILAR TO</primary>
3101    </indexterm>
3102    <indexterm>
3103     <primary>substring</primary>
3104    </indexterm>
3105
3106 <synopsis>
3107 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3108 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3109 </synopsis>
3110
3111    <para>
3112     The <function>SIMILAR TO</function> operator returns true or
3113     false depending on whether its pattern matches the given string.
3114     It is similar to <function>LIKE</function>, except that it
3115     interprets the pattern using the SQL standard's definition of a
3116     regular expression.  SQL regular expressions are a curious cross
3117     between <function>LIKE</function> notation and common regular
3118     expression notation.
3119    </para>
3120
3121    <para>
3122     Like <function>LIKE</function>, the <function>SIMILAR TO</function>
3123     operator succeeds only if its pattern matches the entire string;
3124     this is unlike common regular expression behavior where the pattern
3125     can match any part of the string.
3126     Also like
3127     <function>LIKE</function>, <function>SIMILAR TO</function> uses
3128     <literal>_</> and <literal>%</> as wildcard characters denoting
3129     any single character and any string, respectively (these are
3130     comparable to <literal>.</> and <literal>.*</> in POSIX regular
3131     expressions).
3132    </para>
3133
3134    <para>
3135     In addition to these facilities borrowed from <function>LIKE</function>,
3136     <function>SIMILAR TO</function> supports these pattern-matching
3137     metacharacters borrowed from POSIX regular expressions:
3138
3139    <itemizedlist>
3140     <listitem>
3141      <para>
3142       <literal>|</literal> denotes alternation (either of two alternatives).
3143      </para>
3144     </listitem>
3145     <listitem>
3146      <para>
3147       <literal>*</literal> denotes repetition of the previous item zero
3148       or more times.
3149      </para>
3150     </listitem>
3151     <listitem>
3152      <para>
3153       <literal>+</literal> denotes repetition of the previous item one
3154       or more times.
3155      </para>
3156     </listitem>
3157     <listitem>
3158      <para>
3159       Parentheses <literal>()</literal> can be used to group items into
3160       a single logical item.
3161      </para>
3162     </listitem>
3163     <listitem>
3164      <para>
3165       A bracket expression <literal>[...]</literal> specifies a character
3166       class, just as in POSIX regular expressions.
3167      </para>
3168     </listitem>
3169    </itemizedlist>
3170
3171     Notice that bounded repetition operators (<literal>?</> and
3172     <literal>{...}</>) are not provided, though they exist in POSIX.
3173     Also, the period (<literal>.</>) is not a metacharacter.
3174    </para>
3175
3176    <para>
3177     As with <function>LIKE</>, a backslash disables the special meaning
3178     of any of these metacharacters; or a different escape character can
3179     be specified with <literal>ESCAPE</>.
3180    </para>
3181
3182    <para>
3183     Some examples:
3184 <programlisting>
3185 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
3186 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
3187 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
3188 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
3189 </programlisting>
3190    </para>
3191
3192    <para>
3193     The <function>substring</> function with three parameters,
3194     <function>substring(<replaceable>string</replaceable> from
3195     <replaceable>pattern</replaceable> for
3196     <replaceable>escape-character</replaceable>)</function>, provides
3197     extraction of a substring that matches an SQL
3198     regular expression pattern.  As with <literal>SIMILAR TO</>, the
3199     specified pattern must match the entire data string, or else the
3200     function fails and returns null.  To indicate the part of the
3201     pattern that should be returned on success, the pattern must contain
3202     two occurrences of the escape character followed by a double quote
3203     (<literal>"</>). <!-- " font-lock sanity -->
3204     The text matching the portion of the pattern
3205     between these markers is returned.
3206    </para>
3207
3208    <para>
3209     Some examples, with <literal>#"</> delimiting the return string:
3210 <programlisting>
3211 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
3212 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
3213 </programlisting>
3214    </para>
3215   </sect2>
3216
3217   <sect2 id="functions-posix-regexp">
3218    <title><acronym>POSIX</acronym> Regular Expressions</title>
3219
3220    <indexterm zone="functions-posix-regexp">
3221     <primary>regular expression</primary>
3222     <seealso>pattern matching</seealso>
3223    </indexterm>
3224    <indexterm>
3225     <primary>substring</primary>
3226    </indexterm>
3227    <indexterm>
3228     <primary>regexp_replace</primary>
3229    </indexterm>
3230    <indexterm>
3231     <primary>regexp_matches</primary>
3232    </indexterm>
3233    <indexterm>
3234     <primary>regexp_split_to_table</primary>
3235    </indexterm>
3236    <indexterm>
3237     <primary>regexp_split_to_array</primary>
3238    </indexterm>
3239
3240    <para>
3241     <xref linkend="functions-posix-table"> lists the available
3242     operators for pattern matching using POSIX regular expressions.
3243    </para>
3244
3245    <table id="functions-posix-table">
3246     <title>Regular Expression Match Operators</title>
3247
3248     <tgroup cols="3">
3249      <thead>
3250       <row>
3251        <entry>Operator</entry>
3252        <entry>Description</entry>
3253        <entry>Example</entry>
3254       </row>
3255      </thead>
3256
3257       <tbody>
3258        <row>
3259         <entry> <literal>~</literal> </entry>
3260         <entry>Matches regular expression, case sensitive</entry>
3261         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3262        </row>
3263
3264        <row>
3265         <entry> <literal>~*</literal> </entry>
3266         <entry>Matches regular expression, case insensitive</entry>
3267         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3268        </row>
3269
3270        <row>
3271         <entry> <literal>!~</literal> </entry>
3272         <entry>Does not match regular expression, case sensitive</entry>
3273         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3274        </row>
3275
3276        <row>
3277         <entry> <literal>!~*</literal> </entry>
3278         <entry>Does not match regular expression, case insensitive</entry>
3279         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3280        </row>
3281       </tbody>
3282      </tgroup>
3283     </table>
3284
3285     <para>
3286      <acronym>POSIX</acronym> regular expressions provide a more
3287      powerful means for 
3288      pattern matching than the <function>LIKE</function> and
3289      <function>SIMILAR TO</> operators.
3290      Many Unix tools such as <command>egrep</command>,
3291      <command>sed</command>, or <command>awk</command> use a pattern
3292      matching language that is similar to the one described here.
3293     </para>
3294
3295     <para>
3296      A regular expression is a character sequence that is an
3297      abbreviated definition of a set of strings (a <firstterm>regular
3298      set</firstterm>).  A string is said to match a regular expression
3299      if it is a member of the regular set described by the regular
3300      expression.  As with <function>LIKE</function>, pattern characters
3301      match string characters exactly unless they are special characters
3302      in the regular expression language &mdash; but regular expressions use
3303      different special characters than <function>LIKE</function> does.
3304      Unlike <function>LIKE</function> patterns, a
3305      regular expression is allowed to match anywhere within a string, unless
3306      the regular expression is explicitly anchored to the beginning or
3307      end of the string.
3308     </para>
3309
3310     <para>
3311      Some examples:
3312 <programlisting>
3313 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
3314 'abc' ~ '^a'     <lineannotation>true</lineannotation>
3315 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
3316 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3317 </programlisting>
3318     </para>
3319
3320     <para>
3321      The <acronym>POSIX</acronym> pattern language is described in much
3322      greater detail below.
3323     </para>
3324
3325     <para>
3326      The <function>substring</> function with two parameters,
3327      <function>substring(<replaceable>string</replaceable> from
3328      <replaceable>pattern</replaceable>)</function>, provides extraction of a
3329      substring
3330      that matches a POSIX regular expression pattern.  It returns null if
3331      there is no match, otherwise the portion of the text that matched the
3332      pattern.  But if the pattern contains any parentheses, the portion
3333      of the text that matched the first parenthesized subexpression (the
3334      one whose left parenthesis comes first) is
3335      returned.  You can put parentheses around the whole expression
3336      if you want to use parentheses within it without triggering this
3337      exception.  If you need parentheses in the pattern before the
3338      subexpression you want to extract, see the non-capturing parentheses
3339      described below.
3340     </para>
3341
3342    <para>
3343     Some examples:
3344 <programlisting>
3345 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
3346 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
3347 </programlisting>
3348    </para>
3349
3350     <para>
3351      The <function>regexp_replace</> function provides substitution of
3352      new text for substrings that match POSIX regular expression patterns.
3353      It has the syntax
3354      <function>regexp_replace</function>(<replaceable>source</>,
3355      <replaceable>pattern</>, <replaceable>replacement</>
3356      <optional>, <replaceable>flags</> </optional>).
3357      The <replaceable>source</> string is returned unchanged if
3358      there is no match to the <replaceable>pattern</>.  If there is a
3359      match, the <replaceable>source</> string is returned with the
3360      <replaceable>replacement</> string substituted for the matching
3361      substring.  The <replaceable>replacement</> string can contain
3362      <literal>\</><replaceable>n</>, where <replaceable>n</> is <literal>1</>
3363      through <literal>9</>, to indicate that the source substring matching the
3364      <replaceable>n</>'th parenthesized subexpression of the pattern should be
3365      inserted, and it can contain <literal>\&amp;</> to indicate that the
3366      substring matching the entire pattern should be inserted.  Write
3367      <literal>\\</> if you need to put a literal backslash in the replacement
3368      text.  (As always, remember to double backslashes written in literal
3369      constant strings, assuming escape string syntax is used.)
3370      The <replaceable>flags</> parameter is an optional text
3371      string containing zero or more single-letter flags that change the
3372      function's behavior.  Flag <literal>i</> specifies case-insensitive
3373      matching, while flag <literal>g</> specifies replacement of each matching
3374      substring rather than only the first one.  Other supported flags are
3375      described in <xref linkend="posix-embedded-options-table">.
3376     </para>
3377
3378    <para>
3379     Some examples:
3380 <programlisting>
3381 regexp_replace('foobarbaz', 'b..', 'X')
3382                                    <lineannotation>fooXbaz</lineannotation>
3383 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3384                                    <lineannotation>fooXX</lineannotation>
3385 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3386                                    <lineannotation>fooXarYXazY</lineannotation>
3387 </programlisting>
3388    </para>
3389
3390     <para>
3391      The <function>regexp_matches</> function returns all of the captured
3392      substrings resulting from matching a POSIX regular expression pattern.
3393      It has the syntax
3394      <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3395      <optional>, <replaceable>flags</> </optional>).
3396      If there is no match to the <replaceable>pattern</>, the function returns
3397      no rows.  If there is a match, the function returns a text array whose
3398      <replaceable>n</>'th element is the substring matching the
3399      <replaceable>n</>'th parenthesized subexpression of the pattern
3400      (not counting <quote>non-capturing</> parentheses; see below for
3401      details).  If the pattern does not contain any parenthesized
3402      subexpressions, then the result is a single-element text array containing
3403      the substring matching the whole pattern.
3404      The <replaceable>flags</> parameter is an optional text
3405      string containing zero or more single-letter flags that change the
3406      function's behavior.  Flag <literal>g</> causes the function to find
3407      each match in the string, not only the first one, and return a row for
3408      each such match.  Other supported
3409      flags are described in <xref linkend="posix-embedded-options-table">.
3410     </para>
3411
3412    <para>
3413     Some examples:
3414 <programlisting>
3415 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3416  regexp_matches 
3417 ----------------
3418  {bar,beque}
3419 (1 row)
3420
3421 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3422  regexp_matches 
3423 ----------------
3424  {bar,beque}
3425  {bazil,barf}
3426 (2 rows)
3427
3428 SELECT regexp_matches('foobarbequebaz', 'barbeque');
3429  regexp_matches 
3430 ----------------
3431  {barbeque}
3432 (1 row)
3433 </programlisting>
3434    </para>
3435
3436     <para>
3437      The <function>regexp_split_to_table</> function splits a string using a POSIX
3438      regular expression pattern as a delimiter.  It has the syntax
3439      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
3440      <optional>, <replaceable>flags</> </optional>).
3441      If there is no match to the <replaceable>pattern</>, the function returns the
3442      <replaceable>string</>.  If there is at least one match, for each match it returns
3443      the text from the end of the last match (or the beginning of the string)
3444      to the beginning of the match.  When there are no more matches, it
3445      returns the text from the end of the last match to the end of the string.
3446      The <replaceable>flags</> parameter is an optional text string containing
3447      zero or more single-letter flags that change the function's behavior.
3448      <function>regexp_split_to_table</function> supports the flags described in
3449      <xref linkend="posix-embedded-options-table">.
3450     </para>
3451
3452     <para>
3453      The <function>regexp_split_to_array</> function behaves the same as
3454      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
3455      returns its result as an array of <type>text</>.  It has the syntax
3456      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
3457      <optional>, <replaceable>flags</> </optional>).
3458      The parameters are the same as for <function>regexp_split_to_table</>.
3459     </para>
3460
3461    <para>
3462     Some examples:
3463 <programlisting>
3464
3465 SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\s+') AS foo;
3466   foo   
3467 --------
3468  the    
3469  quick  
3470  brown  
3471  fox    
3472  jumped 
3473  over   
3474  the    
3475  lazy   
3476  dog    
3477 (9 rows)
3478
3479 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
3480               regexp_split_to_array             
3481 ------------------------------------------------
3482  {the,quick,brown,fox,jumped,over,the,lazy,dog}
3483 (1 row)
3484
3485 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
3486  foo 
3487 -----
3488  t         
3489  h         
3490  e         
3491  q         
3492  u         
3493  i         
3494  c         
3495  k         
3496  b         
3497  r         
3498  o         
3499  w         
3500  n         
3501  f         
3502  o         
3503  x         
3504 (16 rows)
3505 </programlisting>
3506    </para>
3507
3508    <para>
3509     As the last example demonstrates, the regexp split functions ignore
3510     zero-length matches that occur at the start or end of the string
3511     or immediately after a previous match.  This is contrary to the strict
3512     definition of regexp matching that is implemented by
3513     <function>regexp_matches</>, but is usually the most convenient behavior
3514     in practice.  Other software systems such as Perl use similar definitions.
3515    </para>
3516
3517 <!-- derived from the re_syntax.n man page -->
3518
3519    <sect3 id="posix-syntax-details">
3520     <title>Regular Expression Details</title>
3521
3522    <para>
3523     <productname>PostgreSQL</productname>'s regular expressions are implemented
3524     using a software package written by Henry Spencer.  Much of
3525     the description of regular expressions below is copied verbatim from his
3526     manual.
3527    </para>
3528
3529    <para>
3530     Regular expressions (<acronym>RE</acronym>s), as defined in
3531     <acronym>POSIX</acronym> 1003.2, come in two forms:
3532     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
3533     (roughly those of <command>egrep</command>), and
3534     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
3535     (roughly those of <command>ed</command>).
3536     <productname>PostgreSQL</productname> supports both forms, and
3537     also implements some extensions
3538     that are not in the POSIX standard, but have become widely used
3539     due to their availability in programming languages such as Perl and Tcl.
3540     <acronym>RE</acronym>s using these non-POSIX extensions are called
3541     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
3542     in this documentation.  AREs are almost an exact superset of EREs,
3543     but BREs have several notational incompatibilities (as well as being
3544     much more limited).
3545     We first describe the ARE and ERE forms, noting features that apply
3546     only to AREs, and then describe how BREs differ.
3547    </para>
3548
3549    <note>
3550     <para>
3551      The form of regular expressions accepted by
3552      <productname>PostgreSQL</> can be chosen by setting the <xref
3553      linkend="guc-regex-flavor"> run-time parameter.  The usual
3554      setting is <literal>advanced</>, but one might choose
3555      <literal>extended</> for backwards compatibility with
3556      pre-7.4 releases of <productname>PostgreSQL</>.
3557     </para>
3558    </note>
3559
3560    <para>
3561     A regular expression is defined as one or more
3562     <firstterm>branches</firstterm>, separated by
3563     <literal>|</literal>.  It matches anything that matches one of the
3564     branches.
3565    </para>
3566
3567    <para>
3568     A branch is zero or more <firstterm>quantified atoms</> or
3569     <firstterm>constraints</>, concatenated.
3570     It matches a match for the first, followed by a match for the second, etc;
3571     an empty branch matches the empty string.
3572    </para>
3573
3574    <para>
3575     A quantified atom is an <firstterm>atom</> possibly followed
3576     by a single <firstterm>quantifier</>.
3577     Without a quantifier, it matches a match for the atom.
3578     With a quantifier, it can match some number of matches of the atom.
3579     An <firstterm>atom</firstterm> can be any of the possibilities
3580     shown in <xref linkend="posix-atoms-table">.
3581     The possible quantifiers and their meanings are shown in
3582     <xref linkend="posix-quantifiers-table">.
3583    </para>
3584
3585    <para>
3586     A <firstterm>constraint</> matches an empty string, but matches only when
3587     specific conditions are met.  A constraint can be used where an atom
3588     could be used, except it cannot be followed by a quantifier.
3589     The simple constraints are shown in
3590     <xref linkend="posix-constraints-table">;
3591     some more constraints are described later.
3592    </para>
3593
3594
3595    <table id="posix-atoms-table">
3596     <title>Regular Expression Atoms</title>
3597
3598     <tgroup cols="2">
3599      <thead>
3600       <row>
3601        <entry>Atom</entry>
3602        <entry>Description</entry>
3603       </row>
3604      </thead>
3605
3606       <tbody>
3607        <row>
3608        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3609        <entry> (where <replaceable>re</> is any regular expression)
3610        matches a match for
3611        <replaceable>re</>, with the match noted for possible reporting </entry>
3612        </row>
3613
3614        <row>
3615        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3616        <entry> as above, but the match is not noted for reporting
3617        (a <quote>non-capturing</> set of parentheses)
3618        (AREs only) </entry>
3619        </row>
3620
3621        <row>
3622        <entry> <literal>.</> </entry>
3623        <entry> matches any single character </entry>
3624        </row>
3625
3626        <row>
3627        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
3628        <entry> a <firstterm>bracket expression</>,
3629        matching any one of the <replaceable>chars</> (see
3630        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
3631        </row>
3632
3633        <row>
3634        <entry> <literal>\</><replaceable>k</> </entry>
3635        <entry> (where <replaceable>k</> is a non-alphanumeric character)
3636        matches that character taken as an ordinary character,
3637        e.g., <literal>\\</> matches a backslash character </entry>
3638        </row>
3639
3640        <row>
3641        <entry> <literal>\</><replaceable>c</> </entry>
3642        <entry> where <replaceable>c</> is alphanumeric
3643        (possibly followed by other characters)
3644        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
3645        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
3646        </row>
3647
3648        <row>
3649        <entry> <literal>{</> </entry>
3650        <entry> when followed by a character other than a digit,
3651        matches the left-brace character <literal>{</>;
3652        when followed by a digit, it is the beginning of a
3653        <replaceable>bound</> (see below) </entry>
3654        </row>
3655
3656        <row>
3657        <entry> <replaceable>x</> </entry>
3658        <entry> where <replaceable>x</> is a single character with no other
3659        significance, matches that character </entry>
3660        </row>
3661       </tbody>
3662      </tgroup>
3663     </table>
3664
3665    <para>
3666     An RE cannot end with <literal>\</>.
3667    </para>
3668
3669    <note>
3670     <para>
3671      Remember that the backslash (<literal>\</literal>) already has a special
3672      meaning in <productname>PostgreSQL</> string literals.
3673      To write a pattern constant that contains a backslash,
3674      you must write two backslashes in the statement, assuming escape
3675      string syntax is used (see <xref linkend="sql-syntax-strings">).
3676     </para>
3677    </note>
3678
3679    <table id="posix-quantifiers-table">
3680     <title>Regular Expression Quantifiers</title>
3681
3682     <tgroup cols="2">
3683      <thead>
3684       <row>
3685        <entry>Quantifier</entry>
3686        <entry>Matches</entry>
3687       </row>
3688      </thead>
3689
3690       <tbody>
3691        <row>
3692        <entry> <literal>*</> </entry>
3693        <entry> a sequence of 0 or more matches of the atom </entry>
3694        </row>
3695
3696        <row>
3697        <entry> <literal>+</> </entry>
3698        <entry> a sequence of 1 or more matches of the atom </entry>
3699        </row>
3700
3701        <row>
3702        <entry> <literal>?</> </entry>
3703        <entry> a sequence of 0 or 1 matches of the atom </entry>
3704        </row>
3705
3706        <row>
3707        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
3708        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
3709        </row>
3710
3711        <row>
3712        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
3713        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
3714        </row>
3715
3716        <row>
3717        <entry>
3718        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3719        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
3720        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
3721        <replaceable>n</> </entry>
3722        </row>
3723
3724        <row>
3725        <entry> <literal>*?</> </entry>
3726        <entry> non-greedy version of <literal>*</> </entry>
3727        </row>
3728
3729        <row>
3730        <entry> <literal>+?</> </entry>
3731        <entry> non-greedy version of <literal>+</> </entry>
3732        </row>
3733
3734        <row>
3735        <entry> <literal>??</> </entry>
3736        <entry> non-greedy version of <literal>?</> </entry>
3737        </row>
3738
3739        <row>
3740        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
3741        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
3742        </row>
3743
3744        <row>
3745        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
3746        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
3747        </row>
3748
3749        <row>
3750        <entry>
3751        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
3752        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3753        </row>
3754       </tbody>
3755      </tgroup>
3756     </table>
3757
3758    <para>
3759     The forms using <literal>{</><replaceable>...</><literal>}</>
3760     are known as <firstterm>bounds</>.
3761     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
3762     unsigned decimal integers with permissible values from 0 to 255 inclusive.
3763    </para>
3764
3765     <para>
3766      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
3767      same possibilities as their corresponding normal (<firstterm>greedy</>)
3768      counterparts, but prefer the smallest number rather than the largest
3769      number of matches.
3770      See <xref linkend="posix-matching-rules"> for more detail.
3771    </para>
3772
3773    <note>
3774     <para>
3775      A quantifier cannot immediately follow another quantifier, e.g.,
3776      <literal>**</> is invalid.
3777      A quantifier cannot
3778      begin an expression or subexpression or follow
3779      <literal>^</literal> or <literal>|</literal>.
3780     </para>
3781    </note>
3782
3783    <table id="posix-constraints-table">
3784     <title>Regular Expression Constraints</title>
3785
3786     <tgroup cols="2">
3787      <thead>
3788       <row>
3789        <entry>Constraint</entry>
3790        <entry>Description</entry>
3791       </row>
3792      </thead>
3793
3794       <tbody>
3795        <row>
3796        <entry> <literal>^</> </entry>
3797        <entry> matches at the beginning of the string </entry>
3798        </row>
3799
3800        <row>
3801        <entry> <literal>$</> </entry>
3802        <entry> matches at the end of the string </entry>
3803        </row>
3804
3805        <row>
3806        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
3807        <entry> <firstterm>positive lookahead</> matches at any point
3808        where a substring matching <replaceable>re</> begins
3809        (AREs only) </entry>
3810        </row>
3811
3812        <row>
3813        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
3814        <entry> <firstterm>negative lookahead</> matches at any point
3815        where no substring matching <replaceable>re</> begins
3816        (AREs only) </entry>
3817        </row>
3818       </tbody>
3819      </tgroup>
3820     </table>
3821
3822    <para>
3823     Lookahead constraints cannot contain <firstterm>back references</>
3824     (see <xref linkend="posix-escape-sequences">),
3825     and all parentheses within them are considered non-capturing.
3826    </para>
3827    </sect3>
3828
3829    <sect3 id="posix-bracket-expressions">
3830     <title>Bracket Expressions</title>
3831
3832    <para>
3833     A <firstterm>bracket expression</firstterm> is a list of
3834     characters enclosed in <literal>[]</literal>.  It normally matches
3835     any single character from the list (but see below).  If the list
3836     begins with <literal>^</literal>, it matches any single character
3837     <emphasis>not</> from the rest of the list.
3838     If two characters
3839     in the list are separated by <literal>-</literal>, this is
3840     shorthand for the full range of characters between those two
3841     (inclusive) in the collating sequence,
3842     e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
3843     any decimal digit.  It is illegal for two ranges to share an
3844     endpoint, e.g.,  <literal>a-c-e</literal>.  Ranges are very
3845     collating-sequence-dependent, so portable programs should avoid
3846     relying on them.
3847    </para>
3848
3849    <para>
3850     To include a literal <literal>]</literal> in the list, make it the
3851     first character (after <literal>^</literal>, if that is used).  To
3852     include a literal <literal>-</literal>, make it the first or last
3853     character, or the second endpoint of a range.  To use a literal
3854     <literal>-</literal> as the first endpoint of a range, enclose it
3855     in <literal>[.</literal> and <literal>.]</literal> to make it a
3856     collating element (see below).  With the exception of these characters,
3857     some combinations using <literal>[</literal>
3858     (see next paragraphs), and escapes (AREs only), all other special
3859     characters lose their special significance within a bracket expression.
3860     In particular, <literal>\</literal> is not special when following
3861     ERE or BRE rules, though it is special (as introducing an escape)
3862     in AREs.
3863    </para>
3864
3865    <para>
3866     Within a bracket expression, a collating element (a character, a
3867     multiple-character sequence that collates as if it were a single
3868     character, or a collating-sequence name for either) enclosed in
3869     <literal>[.</literal> and <literal>.]</literal> stands for the
3870     sequence of characters of that collating element.  The sequence is
3871     treated as a single element of the bracket expression's list.  This
3872     allows a bracket
3873     expression containing a multiple-character collating element to
3874     match more than one character, e.g., if the collating sequence
3875     includes a <literal>ch</literal> collating element, then the RE
3876     <literal>[[.ch.]]*c</literal> matches the first five characters of
3877     <literal>chchcc</literal>.
3878    </para>
3879
3880    <note>
3881     <para>
3882      <productname>PostgreSQL</> currently does not support multi-character collating
3883      elements. This information describes possible future behavior.
3884     </para>
3885    </note>
3886
3887    <para>
3888     Within a bracket expression, a collating element enclosed in
3889     <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
3890     class</>, standing for the sequences of characters of all collating
3891     elements equivalent to that one, including itself.  (If there are
3892     no other equivalent collating elements, the treatment is as if the
3893     enclosing delimiters were <literal>[.</literal> and
3894     <literal>.]</literal>.)  For example, if <literal>o</literal> and
3895     <literal>^</literal> are the members of an equivalence class, then
3896     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
3897     <literal>[o^]</literal> are all synonymous.  An equivalence class
3898     cannot be an endpoint of a range.
3899    </para>
3900
3901    <para>
3902     Within a bracket expression, the name of a character class
3903     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
3904     for the list of all characters belonging to that class.  Standard
3905     character class names are: <literal>alnum</literal>,
3906     <literal>alpha</literal>, <literal>blank</literal>,
3907     <literal>cntrl</literal>, <literal>digit</literal>,
3908     <literal>graph</literal>, <literal>lower</literal>,
3909     <literal>print</literal>, <literal>punct</literal>,
3910     <literal>space</literal>, <literal>upper</literal>,
3911     <literal>xdigit</literal>.  These stand for the character classes
3912     defined in
3913     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
3914     A locale can provide others.  A character class cannot be used as
3915     an endpoint of a range.
3916    </para>
3917
3918    <para>
3919     There are two special cases of bracket expressions:  the bracket
3920     expressions <literal>[[:&lt;:]]</literal> and
3921     <literal>[[:&gt;:]]</literal> are constraints,
3922     matching empty strings at the beginning
3923     and end of a word respectively.  A word is defined as a sequence
3924     of word characters that is neither preceded nor followed by word
3925     characters.  A word character is an <literal>alnum</> character (as
3926     defined by
3927     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
3928     or an underscore.  This is an extension, compatible with but not
3929     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
3930     caution in software intended to be portable to other systems.
3931     The constraint escapes described below are usually preferable; they
3932     are no more standard, but are easier to type.
3933    </para>
3934    </sect3>
3935
3936    <sect3 id="posix-escape-sequences">
3937     <title>Regular Expression Escapes</title>
3938
3939    <para>
3940     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
3941     followed by an alphanumeric character. Escapes come in several varieties:
3942     character entry, class shorthands, constraint escapes, and back references.
3943     A <literal>\</> followed by an alphanumeric character but not constituting
3944     a valid escape is illegal in AREs.
3945     In EREs, there are no escapes: outside a bracket expression,
3946     a <literal>\</> followed by an alphanumeric character merely stands for
3947     that character as an ordinary character, and inside a bracket expression,
3948     <literal>\</> is an ordinary character.
3949     (The latter is the one actual incompatibility between EREs and AREs.)
3950    </para>
3951
3952    <para>
3953     <firstterm>Character-entry escapes</> exist to make it easier to specify
3954     non-printing and other inconvenient characters in REs.  They are
3955     shown in <xref linkend="posix-character-entry-escapes-table">.
3956    </para>
3957
3958    <para>
3959     <firstterm>Class-shorthand escapes</> provide shorthands for certain
3960     commonly-used character classes.  They are
3961     shown in <xref linkend="posix-class-shorthand-escapes-table">.
3962    </para>
3963
3964    <para>
3965     A <firstterm>constraint escape</> is a constraint,
3966     matching the empty string if specific conditions are met,
3967     written as an escape.  They are
3968     shown in <xref linkend="posix-constraint-escapes-table">.
3969    </para>
3970
3971    <para>
3972     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
3973     same string matched by the previous parenthesized subexpression specified
3974     by the number <replaceable>n</>
3975     (see <xref linkend="posix-constraint-backref-table">).  For example,
3976     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
3977     but not <literal>bc</> or <literal>cb</>.
3978     The subexpression must entirely precede the back reference in the RE.
3979     Subexpressions are numbered in the order of their leading parentheses.
3980     Non-capturing parentheses do not define subexpressions.
3981    </para>
3982
3983    <note>
3984     <para>
3985      Keep in mind that an escape's leading <literal>\</> will need to be
3986      doubled when entering the pattern as an SQL string constant.  For example:
3987 <programlisting>
3988 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
3989 </programlisting>
3990     </para>
3991    </note>
3992
3993    <table id="posix-character-entry-escapes-table">
3994     <title>Regular Expression Character-Entry Escapes</title>
3995
3996     <tgroup cols="2">
3997      <thead>
3998       <row>
3999        <entry>Escape</entry>
4000        <entry>Description</entry>
4001       </row>
4002      </thead>
4003
4004       <tbody>
4005        <row>
4006        <entry> <literal>\a</> </entry>
4007        <entry> alert (bell) character, as in C </entry>
4008        </row>
4009
4010        <row>
4011        <entry> <literal>\b</> </entry>
4012        <entry> backspace, as in C </entry>
4013        </row>
4014
4015        <row>
4016        <entry> <literal>\B</> </entry>
4017        <entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
4018        doubling </entry>
4019        </row>
4020
4021        <row>
4022        <entry> <literal>\c</><replaceable>X</> </entry>
4023        <entry> (where <replaceable>X</> is any character) the character whose
4024        low-order 5 bits are the same as those of
4025        <replaceable>X</>, and whose other bits are all zero </entry>
4026        </row>
4027
4028        <row>
4029        <entry> <literal>\e</> </entry>
4030        <entry> the character whose collating-sequence name
4031        is <literal>ESC</>,
4032        or failing that, the character with octal value 033 </entry>
4033        </row>
4034
4035        <row>
4036        <entry> <literal>\f</> </entry>
4037        <entry> form feed, as in C </entry>
4038        </row>
4039
4040        <row>
4041        <entry> <literal>\n</> </entry>
4042        <entry> newline, as in C </entry>
4043        </row>
4044
4045        <row>
4046        <entry> <literal>\r</> </entry>
4047        <entry> carriage return, as in C </entry>
4048        </row>
4049
4050        <row>
4051        <entry> <literal>\t</> </entry>
4052        <entry> horizontal tab, as in C </entry>
4053        </row>
4054
4055        <row>
4056        <entry> <literal>\u</><replaceable>wxyz</> </entry>
4057        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4058        the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4059        in the local byte ordering </entry>
4060        </row>
4061
4062        <row>
4063        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4064        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4065        digits)
4066        reserved for a hypothetical Unicode extension to 32 bits
4067        </entry>
4068        </row>
4069
4070        <row>
4071        <entry> <literal>\v</> </entry>
4072        <entry> vertical tab, as in C </entry>
4073        </row>
4074
4075        <row>
4076        <entry> <literal>\x</><replaceable>hhh</> </entry>
4077        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4078        digits)
4079        the character whose hexadecimal value is
4080        <literal>0x</><replaceable>hhh</>
4081        (a single character no matter how many hexadecimal digits are used)
4082        </entry>
4083        </row>
4084
4085        <row>
4086        <entry> <literal>\0</> </entry>
4087        <entry> the character whose value is <literal>0</> (the null byte)</entry>
4088        </row>
4089
4090        <row>
4091        <entry> <literal>\</><replaceable>xy</> </entry>
4092        <entry> (where <replaceable>xy</> is exactly two octal digits,
4093        and is not a <firstterm>back reference</>)
4094        the character whose octal value is
4095        <literal>0</><replaceable>xy</> </entry>
4096        </row>
4097
4098        <row>
4099        <entry> <literal>\</><replaceable>xyz</> </entry>
4100        <entry> (where <replaceable>xyz</> is exactly three octal digits,
4101        and is not a <firstterm>back reference</>)
4102        the character whose octal value is
4103        <literal>0</><replaceable>xyz</> </entry>
4104        </row>
4105       </tbody>
4106      </tgroup>
4107     </table>
4108
4109    <para>
4110     Hexadecimal digits are <literal>0</>-<literal>9</>,
4111     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4112     Octal digits are <literal>0</>-<literal>7</>.
4113    </para>
4114
4115    <para>
4116     The character-entry escapes are always taken as ordinary characters.
4117     For example, <literal>\135</> is <literal>]</> in ASCII, but
4118     <literal>\135</> does not terminate a bracket expression.
4119    </para>
4120
4121    <table id="posix-class-shorthand-escapes-table">
4122     <title>Regular Expression Class-Shorthand Escapes</title>
4123
4124     <tgroup cols="2">
4125      <thead>
4126       <row>
4127        <entry>Escape</entry>
4128        <entry>Description</entry>
4129       </row>
4130      </thead>
4131
4132       <tbody>
4133        <row>
4134        <entry> <literal>\d</> </entry>
4135        <entry> <literal>[[:digit:]]</> </entry>
4136        </row>
4137
4138        <row>
4139        <entry> <literal>\s</> </entry>
4140        <entry> <literal>[[:space:]]</> </entry>
4141        </row>
4142
4143        <row>
4144        <entry> <literal>\w</> </entry>
4145        <entry> <literal>[[:alnum:]_]</>
4146        (note underscore is included) </entry>
4147        </row>
4148
4149        <row>
4150        <entry> <literal>\D</> </entry>
4151        <entry> <literal>[^[:digit:]]</> </entry>
4152        </row>
4153
4154        <row>
4155        <entry> <literal>\S</> </entry>
4156        <entry> <literal>[^[:space:]]</> </entry>
4157        </row>
4158
4159        <row>
4160        <entry> <literal>\W</> </entry>
4161        <entry> <literal>[^[:alnum:]_]</>
4162        (note underscore is included) </entry>
4163        </row>
4164       </tbody>
4165      </tgroup>
4166     </table>
4167
4168    <para>
4169     Within bracket expressions, <literal>\d</>, <literal>\s</>,
4170     and <literal>\w</> lose their outer brackets,
4171     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4172     (So, for example, <literal>[a-c\d]</> is equivalent to
4173     <literal>[a-c[:digit:]]</>.
4174     Also, <literal>[a-c\D]</>, which is equivalent to
4175     <literal>[a-c^[:digit:]]</>, is illegal.)
4176    </para>
4177
4178    <table id="posix-constraint-escapes-table">
4179     <title>Regular Expression Constraint Escapes</title>
4180
4181     <tgroup cols="2">
4182      <thead>
4183       <row>
4184        <entry>Escape</entry>
4185        <entry>Description</entry>
4186       </row>
4187      </thead>
4188
4189       <tbody>
4190        <row>
4191        <entry> <literal>\A</> </entry>
4192        <entry> matches only at the beginning of the string
4193        (see <xref linkend="posix-matching-rules"> for how this differs from
4194        <literal>^</>) </entry>
4195        </row>
4196
4197        <row>
4198        <entry> <literal>\m</> </entry>
4199        <entry> matches only at the beginning of a word </entry>
4200        </row>
4201
4202        <row>
4203        <entry> <literal>\M</> </entry>
4204        <entry> matches only at the end of a word </entry>
4205        </row>
4206
4207        <row>
4208        <entry> <literal>\y</> </entry>
4209        <entry> matches only at the beginning or end of a word </entry>
4210        </row>
4211
4212        <row>
4213        <entry> <literal>\Y</> </entry>
4214        <entry> matches only at a point that is not the beginning or end of a
4215        word </entry>
4216        </row>
4217
4218        <row>
4219        <entry> <literal>\Z</> </entry>
4220        <entry> matches only at the end of the string
4221        (see <xref linkend="posix-matching-rules"> for how this differs from
4222        <literal>$</>) </entry>
4223        </row>
4224       </tbody>
4225      </tgroup>
4226     </table>
4227
4228    <para>
4229     A word is defined as in the specification of
4230     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4231     Constraint escapes are illegal within bracket expressions.
4232    </para>
4233
4234    <table id="posix-constraint-backref-table">
4235     <title>Regular Expression Back References</title>
4236
4237     <tgroup cols="2">
4238      <thead>
4239       <row>
4240        <entry>Escape</entry>
4241        <entry>Description</entry>
4242       </row>
4243      </thead>
4244
4245       <tbody>
4246        <row>
4247        <entry> <literal>\</><replaceable>m</> </entry>
4248        <entry> (where <replaceable>m</> is a nonzero digit)
4249        a back reference to the <replaceable>m</>'th subexpression </entry>
4250        </row>
4251
4252        <row>
4253        <entry> <literal>\</><replaceable>mnn</> </entry>
4254        <entry> (where <replaceable>m</> is a nonzero digit, and
4255        <replaceable>nn</> is some more digits, and the decimal value
4256        <replaceable>mnn</> is not greater than the number of closing capturing
4257        parentheses seen so far) 
4258        a back reference to the <replaceable>mnn</>'th subexpression </entry>
4259        </row>
4260       </tbody>
4261      </tgroup>
4262     </table>
4263
4264    <note>
4265     <para>
4266      There is an inherent ambiguity between octal character-entry
4267      escapes and back references, which is resolved by the following heuristics,
4268      as hinted at above.
4269      A leading zero always indicates an octal escape.
4270      A single non-zero digit, not followed by another digit,
4271      is always taken as a back reference.
4272      A multi-digit sequence not starting with a zero is taken as a back
4273      reference if it comes after a suitable subexpression
4274      (i.e., the number is in the legal range for a back reference),
4275      and otherwise is taken as octal.
4276     </para>
4277    </note>
4278    </sect3>
4279
4280    <sect3 id="posix-metasyntax">
4281     <title>Regular Expression Metasyntax</title>
4282
4283    <para>
4284     In addition to the main syntax described above, there are some special
4285     forms and miscellaneous syntactic facilities available.
4286    </para>
4287
4288    <para>
4289     Normally the flavor of RE being used is determined by
4290     <varname>regex_flavor</>.
4291     However, this can be overridden by a <firstterm>director</> prefix.
4292     If an RE begins with <literal>***:</>,
4293     the rest of the RE is taken as an ARE regardless of
4294     <varname>regex_flavor</>.
4295     If an RE begins with <literal>***=</>,
4296     the rest of the RE is taken to be a literal string,
4297     with all characters considered ordinary characters.
4298    </para>
4299
4300    <para>
4301     An ARE can begin with <firstterm>embedded options</>:
4302     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4303     (where <replaceable>xyz</> is one or more alphabetic characters)
4304     specifies options affecting the rest of the RE.
4305     These options override any previously determined options (including
4306     both the RE flavor and case sensitivity).
4307     The available option letters are
4308     shown in <xref linkend="posix-embedded-options-table">.
4309    </para>
4310
4311    <table id="posix-embedded-options-table">
4312     <title>ARE Embedded-Option Letters</title>
4313
4314     <tgroup cols="2">
4315      <thead>
4316       <row>
4317        <entry>Option</entry>
4318        <entry>Description</entry>
4319       </row>
4320      </thead>
4321
4322       <tbody>
4323        <row>
4324        <entry> <literal>b</> </entry>
4325        <entry> rest of RE is a BRE </entry>
4326        </row>
4327
4328        <row>
4329        <entry> <literal>c</> </entry>
4330        <entry> case-sensitive matching (overrides operator type) </entry>
4331        </row>
4332
4333        <row>
4334        <entry> <literal>e</> </entry>
4335        <entry> rest of RE is an ERE </entry>
4336        </row>
4337
4338        <row>
4339        <entry> <literal>i</> </entry>
4340        <entry> case-insensitive matching (see
4341        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4342        </row>
4343
4344        <row>
4345        <entry> <literal>m</> </entry>
4346        <entry> historical synonym for <literal>n</> </entry>
4347        </row>
4348
4349        <row>
4350        <entry> <literal>n</> </entry>
4351        <entry> newline-sensitive matching (see
4352        <xref linkend="posix-matching-rules">) </entry>
4353        </row>
4354
4355        <row>
4356        <entry> <literal>p</> </entry>
4357        <entry> partial newline-sensitive matching (see
4358        <xref linkend="posix-matching-rules">) </entry>
4359        </row>
4360
4361        <row>
4362        <entry> <literal>q</> </entry>
4363        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4364        characters </entry>
4365        </row>
4366
4367        <row>
4368        <entry> <literal>s</> </entry>
4369        <entry> non-newline-sensitive matching (default) </entry>
4370        </row>
4371
4372        <row>
4373        <entry> <literal>t</> </entry>
4374        <entry> tight syntax (default; see below) </entry>
4375        </row>
4376
4377        <row>
4378        <entry> <literal>w</> </entry>
4379        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4380        (see <xref linkend="posix-matching-rules">) </entry>
4381        </row>
4382
4383        <row>
4384        <entry> <literal>x</> </entry>
4385        <entry> expanded syntax (see below) </entry>
4386        </row>
4387       </tbody>
4388      </tgroup>
4389     </table>
4390
4391    <para>
4392     Embedded options take effect at the <literal>)</> terminating the sequence.
4393     They can appear only at the start of an ARE (after the
4394     <literal>***:</> director if any).
4395    </para>
4396
4397    <para>
4398     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4399     characters are significant, there is an <firstterm>expanded</> syntax,
4400     available by specifying the embedded <literal>x</> option.
4401     In the expanded syntax,
4402     white-space characters in the RE are ignored, as are
4403     all characters between a <literal>#</>
4404     and the following newline (or the end of the RE).  This
4405     permits paragraphing and commenting a complex RE.
4406     There are three exceptions to that basic rule:
4407
4408     <itemizedlist>
4409      <listitem>
4410       <para>
4411        a white-space character or <literal>#</> preceded by <literal>\</> is
4412        retained
4413       </para>
4414      </listitem>
4415      <listitem>
4416       <para>
4417        white space or <literal>#</> within a bracket expression is retained
4418       </para>
4419      </listitem>
4420      <listitem>
4421       <para>
4422        white space and comments cannot appear within multi-character symbols,
4423        such as <literal>(?:</>
4424       </para>
4425      </listitem>
4426     </itemizedlist>
4427
4428     For this purpose, white-space characters are blank, tab, newline, and
4429     any character that belongs to the <replaceable>space</> character class.
4430    </para>
4431
4432    <para>
4433     Finally, in an ARE, outside bracket expressions, the sequence
4434     <literal>(?#</><replaceable>ttt</><literal>)</>
4435     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4436     is a comment, completely ignored.
4437     Again, this is not allowed between the characters of
4438     multi-character symbols, like <literal>(?:</>.
4439     Such comments are more a historical artifact than a useful facility,
4440     and their use is deprecated; use the expanded syntax instead.
4441    </para>
4442
4443    <para>
4444     <emphasis>None</> of these metasyntax extensions is available if
4445     an initial <literal>***=</> director
4446     has specified that the user's input be treated as a literal string
4447     rather than as an RE.
4448    </para>
4449    </sect3>
4450
4451    <sect3 id="posix-matching-rules">
4452     <title>Regular Expression Matching Rules</title>
4453
4454    <para>
4455     In the event that an RE could match more than one substring of a given
4456     string, the RE matches the one starting earliest in the string.
4457     If the RE could match more than one substring starting at that point,
4458     either the longest possible match or the shortest possible match will
4459     be taken, depending on whether the RE is <firstterm>greedy</> or
4460     <firstterm>non-greedy</>.
4461    </para>
4462
4463    <para>
4464     Whether an RE is greedy or not is determined by the following rules:
4465     <itemizedlist>
4466      <listitem>
4467       <para>
4468        Most atoms, and all constraints, have no greediness attribute (because
4469        they cannot match variable amounts of text anyway).
4470       </para>
4471      </listitem>
4472      <listitem>
4473       <para>
4474        Adding parentheses around an RE does not change its greediness.
4475       </para>
4476      </listitem>
4477      <listitem>
4478       <para>
4479        A quantified atom with a fixed-repetition quantifier
4480        (<literal>{</><replaceable>m</><literal>}</>
4481        or
4482        <literal>{</><replaceable>m</><literal>}?</>)
4483        has the same greediness (possibly none) as the atom itself.
4484       </para>
4485      </listitem>
4486      <listitem>
4487       <para>
4488        A quantified atom with other normal quantifiers (including
4489        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4490        with <replaceable>m</> equal to <replaceable>n</>)
4491        is greedy (prefers longest match).
4492       </para>
4493      </listitem>
4494      <listitem>
4495       <para>
4496        A quantified atom with a non-greedy quantifier (including
4497        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4498        with <replaceable>m</> equal to <replaceable>n</>)
4499        is non-greedy (prefers shortest match).
4500       </para>
4501      </listitem>
4502      <listitem>
4503       <para>
4504        A branch &mdash; that is, an RE that has no top-level
4505        <literal>|</> operator &mdash; has the same greediness as the first
4506        quantified atom in it that has a greediness attribute.
4507       </para>
4508      </listitem>
4509      <listitem>
4510       <para>
4511        An RE consisting of two or more branches connected by the
4512        <literal>|</> operator is always greedy.
4513       </para>
4514      </listitem>
4515     </itemizedlist>
4516    </para>
4517
4518    <para>
4519     The above rules associate greediness attributes not only with individual
4520     quantified atoms, but with branches and entire REs that contain quantified
4521     atoms.  What that means is that the matching is done in such a way that
4522     the branch, or whole RE, matches the longest or shortest possible
4523     substring <emphasis>as a whole</>.  Once the length of the entire match
4524     is determined, the part of it that matches any particular subexpression
4525     is determined on the basis of the greediness attribute of that
4526     subexpression, with subexpressions starting earlier in the RE taking
4527     priority over ones starting later.
4528    </para>
4529
4530    <para>
4531     An example of what this means:
4532 <screen>
4533 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4534 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4535 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4536 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4537 </screen>
4538     In the first case, the RE as a whole is greedy because <literal>Y*</>
4539     is greedy.  It can match beginning at the <literal>Y</>, and it matches
4540     the longest possible string starting there, i.e., <literal>Y123</>.
4541     The output is the parenthesized part of that, or <literal>123</>.
4542     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4543     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
4544     the shortest possible string starting there, i.e., <literal>Y1</>.
4545     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4546     the decision as to the overall match length; so it is forced to match
4547     just <literal>1</>.
4548    </para>
4549
4550    <para>
4551     In short, when an RE contains both greedy and non-greedy subexpressions,
4552     the total match length is either as long as possible or as short as
4553     possible, according to the attribute assigned to the whole RE.  The
4554     attributes assigned to the subexpressions only affect how much of that
4555     match they are allowed to <quote>eat</> relative to each other.
4556    </para>
4557
4558    <para>
4559     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4560     can be used to force greediness or non-greediness, respectively,
4561     on a subexpression or a whole RE.
4562    </para>
4563
4564    <para>
4565     Match lengths are measured in characters, not collating elements.
4566     An empty string is considered longer than no match at all.
4567     For example:
4568     <literal>bb*</>
4569     matches the three middle characters of <literal>abbbc</>;
4570     <literal>(week|wee)(night|knights)</>
4571     matches all ten characters of <literal>weeknights</>;
4572     when <literal>(.*).*</>
4573     is matched against <literal>abc</> the parenthesized subexpression
4574     matches all three characters; and when
4575     <literal>(a*)*</> is matched against <literal>bc</>
4576     both the whole RE and the parenthesized
4577     subexpression match an empty string.
4578    </para>
4579
4580    <para>
4581     If case-independent matching is specified,
4582     the effect is much as if all case distinctions had vanished from the
4583     alphabet.
4584     When an alphabetic that exists in multiple cases appears as an
4585     ordinary character outside a bracket expression, it is effectively
4586     transformed into a bracket expression containing both cases,
4587     e.g., <literal>x</> becomes <literal>[xX]</>.
4588     When it appears inside a bracket expression, all case counterparts
4589     of it are added to the bracket expression, e.g.,
4590     <literal>[x]</> becomes <literal>[xX]</>
4591     and <literal>[^x]</> becomes <literal>[^xX]</>.
4592    </para>
4593
4594    <para>
4595     If newline-sensitive matching is specified, <literal>.</>
4596     and bracket expressions using <literal>^</>
4597     will never match the newline character
4598     (so that matches will never cross newlines unless the RE
4599     explicitly arranges it)
4600     and <literal>^</>and <literal>$</>
4601     will match the empty string after and before a newline
4602     respectively, in addition to matching at beginning and end of string
4603     respectively.
4604     But the ARE escapes <literal>\A</> and <literal>\Z</>
4605     continue to match beginning or end of string <emphasis>only</>.
4606    </para>
4607
4608    <para>
4609     If partial newline-sensitive matching is specified,
4610     this affects <literal>.</> and bracket expressions
4611     as with newline-sensitive matching, but not <literal>^</>
4612     and <literal>$</>.
4613    </para>
4614
4615    <para>
4616     If inverse partial newline-sensitive matching is specified,
4617     this affects <literal>^</> and <literal>$</>
4618     as with newline-sensitive matching, but not <literal>.</>
4619     and bracket expressions.
4620     This isn't very useful but is provided for symmetry.
4621    </para>
4622    </sect3>
4623
4624    <sect3 id="posix-limits-compatibility">
4625     <title>Limits and Compatibility</title>
4626
4627    <para>
4628     No particular limit is imposed on the length of REs in this
4629     implementation.  However,
4630     programs intended to be highly portable should not employ REs longer
4631     than 256 bytes,
4632     as a POSIX-compliant implementation can refuse to accept such REs.
4633    </para>
4634
4635    <para>
4636     The only feature of AREs that is actually incompatible with
4637     POSIX EREs is that <literal>\</> does not lose its special
4638     significance inside bracket expressions.
4639     All other ARE features use syntax which is illegal or has
4640     undefined or unspecified effects in POSIX EREs;
4641     the <literal>***</> syntax of directors likewise is outside the POSIX
4642     syntax for both BREs and EREs.
4643    </para>
4644
4645    <para>
4646     Many of the ARE extensions are borrowed from Perl, but some have
4647     been changed to clean them up, and a few Perl extensions are not present.
4648     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
4649     the lack of special treatment for a trailing newline,
4650     the addition of complemented bracket expressions to the things
4651     affected by newline-sensitive matching,
4652     the restrictions on parentheses and back references in lookahead
4653     constraints, and the longest/shortest-match (rather than first-match)
4654     matching semantics.
4655    </para>
4656
4657    <para>
4658     Two significant incompatibilities exist between AREs and the ERE syntax
4659     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
4660
4661     <itemizedlist>
4662      <listitem>
4663       <para>
4664        In AREs, <literal>\</> followed by an alphanumeric character is either
4665        an escape or an error, while in previous releases, it was just another
4666        way of writing the alphanumeric.
4667        This should not be much of a problem because there was no reason to
4668        write such a sequence in earlier releases.
4669       </para>
4670      </listitem>
4671      <listitem>
4672       <para>
4673        In AREs, <literal>\</> remains a special character within
4674        <literal>[]</>, so a literal <literal>\</> within a bracket
4675        expression must be written <literal>\\</>.
4676       </para>
4677      </listitem>
4678     </itemizedlist>
4679
4680     While these differences are unlikely to create a problem for most
4681     applications, you can avoid them if necessary by
4682     setting <varname>regex_flavor</> to <literal>extended</>.
4683    </para>
4684    </sect3>
4685
4686    <sect3 id="posix-basic-regexes">
4687     <title>Basic Regular Expressions</title>
4688
4689    <para>
4690     BREs differ from EREs in several respects.
4691     In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
4692     are ordinary characters and there is no equivalent
4693     for their functionality.
4694     The delimiters for bounds are
4695     <literal>\{</> and <literal>\}</>,
4696     with <literal>{</> and <literal>}</>
4697     by themselves ordinary characters.
4698     The parentheses for nested subexpressions are
4699     <literal>\(</> and <literal>\)</>,
4700     with <literal>(</> and <literal>)</> by themselves ordinary characters.
4701     <literal>^</> is an ordinary character except at the beginning of the
4702     RE or the beginning of a parenthesized subexpression,
4703     <literal>$</> is an ordinary character except at the end of the
4704     RE or the end of a parenthesized subexpression,
4705     and <literal>*</> is an ordinary character if it appears at the beginning
4706     of the RE or the beginning of a parenthesized subexpression
4707     (after a possible leading <literal>^</>).
4708     Finally, single-digit back references are available, and
4709     <literal>\&lt;</> and <literal>\&gt;</>
4710     are synonyms for
4711     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
4712     respectively; no other escapes are available in BREs.
4713    </para>
4714    </sect3>
4715
4716 <!-- end re_syntax.n man page -->
4717
4718   </sect2>
4719  </sect1>
4720
4721
4722   <sect1 id="functions-formatting">
4723    <title>Data Type Formatting Functions</title>
4724
4725    <indexterm>
4726     <primary>formatting</primary>
4727    </indexterm>
4728
4729    <indexterm>
4730     <primary>to_char</primary>
4731    </indexterm>
4732    <indexterm>
4733     <primary>to_date</primary>
4734    </indexterm>
4735    <indexterm>
4736     <primary>to_number</primary>
4737    </indexterm>
4738    <indexterm>
4739     <primary>to_timestamp</primary>
4740    </indexterm>
4741
4742    <para>
4743     The <productname>PostgreSQL</productname> formatting functions
4744     provide a powerful set of tools for converting various data types
4745     (date/time, integer, floating point, numeric) to formatted strings
4746     and for converting from formatted strings to specific data types.
4747     <xref linkend="functions-formatting-table"> lists them.
4748     These functions all follow a common calling convention: the first
4749     argument is the value to be formatted and the second argument is a
4750     template that defines the output or input format.
4751    </para>
4752    <para>
4753     A single-argument <function>to_timestamp</function> function is also
4754     available;  it accepts a
4755     <type>double precision</type> argument and converts from Unix epoch
4756     (seconds since 1970-01-01 00:00:00+00) to
4757     <type>timestamp with time zone</type>.
4758     (<type>Integer</type> Unix epochs are implicitly cast to
4759     <type>double precision</type>.)
4760    </para>
4761
4762     <table id="functions-formatting-table">
4763      <title>Formatting Functions</title>
4764      <tgroup cols="4">
4765       <thead>
4766        <row>
4767         <entry>Function</entry>
4768         <entry>Return Type</entry>
4769         <entry>Description</entry>
4770         <entry>Example</entry>
4771        </row>
4772       </thead>
4773       <tbody>
4774        <row>
4775         <entry><literal><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</literal></entry>
4776         <entry><type>text</type></entry>
4777         <entry>convert time stamp to string</entry>
4778         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
4779        </row>
4780        <row>
4781         <entry><literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal></entry>
4782         <entry><type>text</type></entry>
4783         <entry>convert interval to string</entry>
4784         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
4785        </row>
4786        <row>
4787         <entry><literal><function>to_char</function>(<type>int</type>, <type>text</type>)</literal></entry>
4788         <entry><type>text</type></entry>
4789         <entry>convert integer to string</entry>
4790         <entry><literal>to_char(125, '999')</literal></entry>
4791        </row>
4792        <row>
4793         <entry><literal><function>to_char</function>(<type>double precision</type>,
4794         <type>text</type>)</literal></entry>
4795         <entry><type>text</type></entry>
4796         <entry>convert real/double precision to string</entry>
4797         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
4798        </row>
4799        <row>
4800         <entry><literal><function>to_char</function>(<type>numeric</type>, <type>text</type>)</literal></entry>
4801         <entry><type>text</type></entry>
4802         <entry>convert numeric to string</entry>
4803         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
4804        </row>
4805        <row>
4806         <entry><literal><function>to_date</function>(<type>text</type>, <type>text</type>)</literal></entry>
4807         <entry><type>date</type></entry>
4808         <entry>convert string to date</entry>
4809         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4810        </row>
4811        <row>
4812         <entry><literal><function>to_number</function>(<type>text</type>, <type>text</type>)</literal></entry>
4813         <entry><type>numeric</type></entry>
4814         <entry>convert string to numeric</entry>
4815         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
4816        </row>
4817        <row>
4818         <entry><literal><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</literal></entry>
4819         <entry><type>timestamp with time zone</type></entry>
4820         <entry>convert string to time stamp</entry>
4821         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4822        </row>
4823        <row>
4824         <entry><literal><function>to_timestamp</function>(<type>double precision</type>)</literal></entry>
4825         <entry><type>timestamp with time zone</type></entry>
4826         <entry>convert Unix epoch to time stamp</entry>
4827         <entry><literal>to_timestamp(1284352323)</literal></entry>
4828        </row>
4829       </tbody>
4830      </tgroup>
4831     </table>
4832
4833    <para>
4834     In a <function>to_char</> output template string, there are certain
4835     patterns that are recognized and replaced with appropriately-formatted
4836     data based on the given value.  Any text that is not a template pattern is
4837     simply copied verbatim.  Similarly, in an input template string (for the
4838     other functions), template patterns identify the values to be supplied by
4839     the input data string.
4840    </para>
4841
4842   <para>
4843    <xref linkend="functions-formatting-datetime-table"> shows the
4844    template patterns available for formatting date and time values.
4845   </para>
4846
4847     <table id="functions-formatting-datetime-table">
4848      <title>Template Patterns for Date/Time Formatting</title>
4849      <tgroup cols="2">
4850       <thead>
4851        <row>
4852         <entry>Pattern</entry>
4853         <entry>Description</entry>
4854        </row>
4855       </thead>
4856       <tbody>
4857        <row>
4858         <entry><literal>HH</literal></entry>
4859         <entry>hour of day (01-12)</entry>
4860        </row>
4861        <row>
4862         <entry><literal>HH12</literal></entry>
4863         <entry>hour of day (01-12)</entry>
4864        </row>       
4865        <row>
4866         <entry><literal>HH24</literal></entry>
4867         <entry>hour of day (00-23)</entry>
4868        </row>       
4869        <row>
4870         <entry><literal>MI</literal></entry>
4871         <entry>minute (00-59)</entry>
4872        </row>   
4873        <row>
4874         <entry><literal>SS</literal></entry>
4875         <entry>second (00-59)</entry>
4876        </row>
4877        <row>
4878         <entry><literal>MS</literal></entry>
4879         <entry>millisecond (000-999)</entry>
4880        </row>
4881        <row>
4882         <entry><literal>US</literal></entry>
4883         <entry>microsecond (000000-999999)</entry>
4884        </row>
4885        <row>
4886         <entry><literal>SSSS</literal></entry>
4887         <entry>seconds past midnight (0-86399)</entry>
4888        </row>
4889        <row>
4890         <entry><literal>AM</literal>, <literal>am</literal>,
4891         <literal>PM</literal> or <literal>pm</literal></entry>
4892         <entry>meridiem indicator (without periods)</entry>
4893        </row>
4894        <row>
4895         <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
4896         <literal>P.M.</literal> or <literal>p.m.</literal></entry>
4897         <entry>meridiem indicator (with periods)</entry>
4898        </row>
4899        <row>
4900         <entry><literal>Y,YYY</literal></entry>
4901         <entry>year (4 and more digits) with comma</entry>
4902        </row>
4903        <row>
4904         <entry><literal>YYYY</literal></entry>
4905         <entry>year (4 and more digits)</entry>
4906        </row>
4907        <row>
4908         <entry><literal>YYY</literal></entry>
4909         <entry>last 3 digits of year</entry>
4910        </row>
4911        <row>
4912         <entry><literal>YY</literal></entry>
4913         <entry>last 2 digits of year</entry>
4914        </row>
4915        <row>
4916         <entry><literal>Y</literal></entry>
4917         <entry>last digit of year</entry>
4918        </row>
4919        <row>
4920         <entry><literal>IYYY</literal></entry>
4921         <entry>ISO year (4 and more digits)</entry>
4922        </row>
4923        <row>
4924         <entry><literal>IYY</literal></entry>
4925         <entry>last 3 digits of ISO year</entry>
4926        </row>
4927        <row>
4928         <entry><literal>IY</literal></entry>
4929         <entry>last 2 digits of ISO year</entry>
4930        </row>
4931        <row>
4932         <entry><literal>I</literal></entry>
4933         <entry>last digit of ISO year</entry>
4934        </row>
4935        <row>
4936         <entry><literal>BC</literal>, <literal>bc</literal>,
4937         <literal>AD</literal> or <literal>ad</literal></entry>
4938         <entry>era indicator (without periods)</entry>
4939        </row>
4940        <row>
4941         <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
4942         <literal>A.D.</literal> or <literal>a.d.</literal></entry>
4943         <entry>era indicator (with periods)</entry>
4944        </row>
4945        <row>
4946         <entry><literal>MONTH</literal></entry>
4947         <entry>full uppercase month name (blank-padded to 9 chars)</entry>
4948        </row>
4949        <row>
4950         <entry><literal>Month</literal></entry>
4951         <entry>full capitalized month name (blank-padded to 9 chars)</entry>
4952        </row>
4953        <row>
4954         <entry><literal>month</literal></entry>
4955         <entry>full lowercase month name (blank-padded to 9 chars)</entry>
4956        </row>
4957        <row>
4958         <entry><literal>MON</literal></entry>
4959         <entry>abbreviated uppercase month name (3 chars in English, localized lengths vary)</entry>
4960        </row>
4961        <row>
4962         <entry><literal>Mon</literal></entry>
4963         <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
4964        </row>
4965        <row>
4966         <entry><literal>mon</literal></entry>
4967         <entry>abbreviated lowercase month name (3 chars in English, localized lengths vary)</entry>
4968        </row>
4969        <row>
4970         <entry><literal>MM</literal></entry>
4971         <entry>month number (01-12)</entry>
4972        </row>
4973        <row>
4974         <entry><literal>DAY</literal></entry>
4975         <entry>full uppercase day name (blank-padded to 9 chars)</entry>
4976        </row>
4977        <row>
4978         <entry><literal>Day</literal></entry>
4979         <entry>full capitalized day name (blank-padded to 9 chars)</entry>
4980        </row>
4981        <row>
4982         <entry><literal>day</literal></entry>
4983         <entry>full lowercase day name (blank-padded to 9 chars)</entry>
4984        </row>
4985        <row>
4986         <entry><literal>DY</literal></entry>
4987         <entry>abbreviated uppercase day name (3 chars in English, localized lengths vary)</entry>
4988        </row>
4989        <row>
4990         <entry><literal>Dy</literal></entry>
4991         <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
4992        </row>
4993        <row>
4994         <entry><literal>dy</literal></entry>
4995         <entry>abbreviated lowercase day name (3 chars in English, localized lengths vary)</entry>
4996        </row>
4997        <row>
4998         <entry><literal>DDD</literal></entry>
4999         <entry>day of year (001-366)</entry>
5000        </row>
5001        <row>
5002         <entry><literal>IDDD</literal></entry>
5003         <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
5004        </row>
5005        <row>
5006         <entry><literal>DD</literal></entry>
5007         <entry>day of month (01-31)</entry>
5008        </row>
5009        <row>
5010         <entry><literal>D</literal></entry>
5011         <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
5012        </row>
5013        <row>
5014         <entry><literal>ID</literal></entry>
5015         <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
5016        </row>
5017        <row>
5018         <entry><literal>W</literal></entry>
5019         <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
5020        </row> 
5021        <row>
5022         <entry><literal>WW</literal></entry>
5023         <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
5024        </row>
5025        <row>
5026         <entry><literal>IW</literal></entry>
5027         <entry>ISO week number of year (01 - 53; the first Thursday of the new year is in week 1.)</entry>
5028        </row>
5029        <row>
5030         <entry><literal>CC</literal></entry>
5031         <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
5032        </row>
5033        <row>
5034         <entry><literal>J</literal></entry>
5035         <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
5036        </row>
5037        <row>
5038         <entry><literal>Q</literal></entry>
5039         <entry>quarter</entry>
5040        </row>
5041        <row>
5042         <entry><literal>RM</literal></entry>
5043         <entry>month in uppercase Roman numerals (I-XII; I=January)</entry>
5044        </row>
5045        <row>
5046         <entry><literal>rm</literal></entry>
5047         <entry>month in lowercase Roman numerals (i-xii; i=January)</entry>
5048        </row>
5049        <row>
5050         <entry><literal>TZ</literal></entry>
5051         <entry>uppercase time-zone name</entry>
5052        </row>
5053        <row>
5054         <entry><literal>tz</literal></entry>
5055         <entry>lowercase time-zone name</entry>
5056        </row>
5057       </tbody>
5058      </tgroup>
5059     </table>
5060
5061    <para>
5062     Modifiers can be applied to any template pattern to alter its
5063     behavior.  For example, <literal>FMMonth</literal>
5064     is the <literal>Month</literal> pattern with the
5065     <literal>FM</literal> modifier.
5066     <xref linkend="functions-formatting-datetimemod-table"> shows the
5067     modifier patterns for date/time formatting.
5068    </para>
5069
5070     <table id="functions-formatting-datetimemod-table">
5071      <title>Template Pattern Modifiers for Date/Time Formatting</title>
5072      <tgroup cols="3">
5073       <thead>
5074        <row>
5075         <entry>Modifier</entry>
5076         <entry>Description</entry>
5077         <entry>Example</entry>
5078        </row>
5079       </thead>
5080       <tbody>
5081        <row>
5082         <entry><literal>FM</literal> prefix</entry>
5083         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5084         <entry><literal>FMMonth</literal></entry>
5085        </row>
5086        <row>
5087         <entry><literal>TH</literal> suffix</entry>
5088         <entry>uppercase ordinal number suffix</entry>
5089         <entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
5090        </row>   
5091        <row>
5092         <entry><literal>th</literal> suffix</entry>
5093         <entry>lowercase ordinal number suffix</entry>
5094         <entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
5095        </row>
5096        <row>
5097         <entry><literal>FX</literal> prefix</entry>
5098         <entry>fixed format global option (see usage notes)</entry>
5099         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5100        </row>   
5101        <row>
5102         <entry><literal>TM</literal> prefix</entry>
5103         <entry>translation mode (print localized day and month names based on
5104          <xref linkend="guc-lc-time">)</entry>
5105         <entry><literal>TMMonth</literal></entry>
5106        </row>       
5107        <row>
5108         <entry><literal>SP</literal> suffix</entry>
5109         <entry>spell mode (not implemented)</entry>
5110         <entry><literal>DDSP</literal></entry>
5111        </row>       
5112       </tbody>
5113      </tgroup>
5114     </table>
5115
5116    <para>
5117     Usage notes for date/time formatting:
5118
5119     <itemizedlist>
5120      <listitem>
5121       <para>
5122        <literal>FM</literal> suppresses leading zeroes and trailing blanks
5123        that would otherwise be added to make the output of a pattern be
5124        fixed-width.
5125       </para>
5126      </listitem>
5127
5128      <listitem>
5129       <para>
5130        <literal>TM</literal> does not include trailing blanks.
5131       </para>
5132      </listitem>
5133
5134      <listitem>
5135       <para>
5136        <function>to_timestamp</function> and <function>to_date</function>
5137        skip multiple blank spaces in the input string unless the
5138        <literal>FX</literal> option is used. For example,
5139        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> works, but
5140        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
5141        because <function>to_timestamp</function> expects one space only.
5142        <literal>FX</literal> must be specified as the first item in
5143        the template.
5144       </para>
5145      </listitem>
5146
5147      <listitem>
5148       <para>
5149        Ordinary text is allowed in <function>to_char</function>
5150        templates and will be output literally.  You can put a substring
5151        in double quotes to force it to be interpreted as literal text
5152        even if it contains pattern key words.  For example, in
5153        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5154        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5155        will not be.
5156       </para>
5157      </listitem>
5158
5159      <listitem>
5160       <para>
5161        If you want to have a double quote in the output you must
5162        precede it with a backslash, for example <literal>E'\\"YYYY
5163        Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
5164        (Two backslashes are necessary because the backslash
5165        has special meaning when using the escape string syntax.)
5166       </para>
5167      </listitem>
5168
5169      <listitem>
5170       <para>
5171        The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5172        <type>date</type> has a restriction when processing years with more than 4 digits. You must
5173        use some non-digit character or template after <literal>YYYY</literal>,
5174        otherwise the year is always interpreted as 4 digits. For example
5175        (with the year 20000):
5176        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
5177        interpreted as a 4-digit year; instead use a non-digit 
5178        separator after the year, like
5179        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5180        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5181       </para>
5182      </listitem>
5183
5184      <listitem>
5185       <para>
5186        In conversions from string to <type>timestamp</type> or
5187        <type>date</type>, the <literal>CC</literal> (century) field is ignored
5188        if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
5189        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5190        <literal>YY</literal> or <literal>Y</literal> then the year is computed
5191        as <literal>(CC-1)*100+YY</literal>.
5192       </para>
5193      </listitem>
5194
5195      <listitem>
5196       <para>
5197        An ISO week date (as distinct from a Gregorian date) can be
5198        specified to <function>to_timestamp</function> and
5199        <function>to_date</function> in one of two ways:
5200        <itemizedlist>
5201         <listitem>
5202          <para>
5203           Year, week, and weekday:  for example <literal>to_date('2006-42-4',
5204           'IYYY-IW-ID')</literal> returns the date
5205           <literal>2006-10-19</literal>.  If you omit the weekday it
5206           is assumed to be 1 (Monday).
5207          </para>
5208         </listitem>
5209         <listitem>
5210          <para>
5211           Year and day of year:  for example <literal>to_date('2006-291',
5212           'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5213          </para>
5214         </listitem>
5215        </itemizedlist>
5216       </para>
5217       <para>
5218        Attempting to construct a date using a mixture of ISO week and
5219        Gregorian date fields is nonsensical, and will cause an error.  In the
5220        context of an ISO year, the concept of a <quote>month</> or <quote>day
5221        of month</> has no meaning.  In the context of a Gregorian year, the
5222        ISO week has no meaning.  Users should avoid mixing Gregorian and
5223        ISO date specifications.
5224       </para>
5225      </listitem>
5226
5227      <listitem>
5228       <para>
5229        In a conversion from string to <type>timestamp</type>, millisecond
5230        (<literal>MS</literal>) or microsecond (<literal>US</literal>)
5231        values are used as the
5232        seconds digits after the decimal point. For example 
5233        <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5234        but 300, because the conversion counts it as 12 + 0.3 seconds.
5235        This means for the format <literal>SS:MS</literal>, the input values
5236        <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5237        same number of milliseconds. To get three milliseconds, one must use
5238        <literal>12:003</literal>, which the conversion counts as
5239        12 + 0.003 = 12.003 seconds.
5240       </para>
5241
5242       <para>
5243        Here is a more 
5244        complex example: 
5245        <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5246        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5247        1230 microseconds = 2.021230 seconds. 
5248       </para>
5249      </listitem>
5250
5251      <listitem>
5252       <para>
5253         <function>to_char(..., 'ID')</function>'s day of the week numbering
5254         matches the <function>extract('isodow', ...)</function> function, but
5255         <function>to_char(..., 'D')</function>'s does not match
5256         <function>extract('dow', ...)</function>'s day numbering.
5257       </para>
5258      </listitem>
5259
5260      <listitem>
5261       <para>
5262         <function>to_char(interval)</function> formats <literal>HH</> and
5263         <literal>HH12</> as hours in a single day, while <literal>HH24</>
5264         can output hours exceeding a single day, e.g., &gt;24.
5265       </para>
5266      </listitem>
5267
5268     </itemizedlist>
5269    </para>
5270
5271   <para>
5272    <xref linkend="functions-formatting-numeric-table"> shows the
5273    template patterns available for formatting numeric values.
5274   </para>
5275
5276     <table id="functions-formatting-numeric-table">
5277      <title>Template Patterns for Numeric Formatting</title>
5278      <tgroup cols="2">
5279       <thead>
5280        <row>
5281         <entry>Pattern</entry>
5282         <entry>Description</entry>
5283        </row>
5284       </thead>
5285       <tbody>
5286        <row>
5287         <entry><literal>9</literal></entry>
5288         <entry>value with the specified number of digits</entry>
5289        </row>
5290        <row>
5291         <entry><literal>0</literal></entry>
5292         <entry>value with leading zeros</entry>
5293        </row>
5294        <row>
5295         <entry><literal>.</literal> (period)</entry>
5296         <entry>decimal point</entry>
5297        </row>       
5298        <row>
5299         <entry><literal>,</literal> (comma)</entry>
5300         <entry>group (thousand) separator</entry>
5301        </row>
5302        <row>
5303         <entry><literal>PR</literal></entry>
5304         <entry>negative value in angle brackets</entry>
5305        </row>
5306        <row>
5307         <entry><literal>S</literal></entry>
5308         <entry>sign anchored to number (uses locale)</entry>
5309        </row>
5310        <row>
5311         <entry><literal>L</literal></entry>
5312         <entry>currency symbol (uses locale)</entry>
5313        </row>
5314        <row>
5315         <entry><literal>D</literal></entry>
5316         <entry>decimal point (uses locale)</entry>
5317        </row>
5318        <row>
5319         <entry><literal>G</literal></entry>
5320         <entry>group separator (uses locale)</entry>
5321        </row>
5322        <row>
5323         <entry><literal>MI</literal></entry>
5324         <entry>minus sign in specified position (if number &lt; 0)</entry>
5325        </row>
5326        <row>
5327         <entry><literal>PL</literal></entry>
5328         <entry>plus sign in specified position (if number &gt; 0)</entry>
5329        </row>
5330        <row>
5331         <entry><literal>SG</literal></entry>
5332         <entry>plus/minus sign in specified position</entry>
5333        </row>
5334        <row>
5335         <entry><literal>RN</literal></entry>
5336         <entry>Roman numeral (input between 1 and 3999)</entry>
5337        </row>
5338        <row>
5339         <entry><literal>TH</literal> or <literal>th</literal></entry>
5340         <entry>ordinal number suffix</entry>
5341        </row>
5342        <row>
5343         <entry><literal>V</literal></entry>
5344         <entry>shift specified number of digits (see notes)</entry>
5345        </row>
5346        <row>
5347         <entry><literal>EEEE</literal></entry>
5348         <entry>exponent for scientific notation</entry>
5349        </row>
5350       </tbody>
5351      </tgroup>
5352     </table>
5353
5354    <para>
5355     Usage notes for numeric formatting:
5356
5357     <itemizedlist>
5358      <listitem>
5359       <para>
5360        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5361        <literal>MI</literal> is not anchored to
5362        the number; for example,
5363        <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
5364        but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
5365        The Oracle implementation does not allow the use of
5366        <literal>MI</literal> before <literal>9</literal>, but rather
5367        requires that <literal>9</literal> precede
5368        <literal>MI</literal>.
5369       </para>
5370      </listitem>
5371
5372      <listitem>
5373       <para>
5374        <literal>9</literal> results in a value with the same number of 
5375        digits as there are <literal>9</literal>s. If a digit is
5376        not available it outputs a space.
5377       </para>
5378      </listitem>
5379
5380      <listitem>
5381       <para>
5382        <literal>TH</literal> does not convert values less than zero
5383        and does not convert fractional numbers.
5384       </para>
5385      </listitem>
5386
5387      <listitem>
5388       <para>
5389        <literal>PL</literal>, <literal>SG</literal>, and
5390        <literal>TH</literal> are <productname>PostgreSQL</productname>
5391        extensions. 
5392       </para>
5393      </listitem>
5394
5395      <listitem>
5396       <para>
5397        <literal>V</literal> effectively
5398        multiplies the input values by
5399        <literal>10^<replaceable>n</replaceable></literal>, where
5400        <replaceable>n</replaceable> is the number of digits following
5401        <literal>V</literal>.
5402        <function>to_char</function> does not support the use of
5403        <literal>V</literal> combined with a decimal point
5404        (e.g., <literal>99.9V99</literal> is not allowed).
5405       </para>
5406      </listitem>
5407
5408      <listitem>
5409       <para>
5410        <literal>EEEE</literal> (scientific notation) cannot be used in
5411        combination with any of the other special formatting patterns or
5412        modifiers, and must be at the end of the format string
5413        (e.g., <literal>9.99EEEE</literal> is a valid pattern).
5414       </para>
5415      </listitem>
5416     </itemizedlist>
5417    </para>
5418
5419    <para>
5420     Certain modifiers can be applied to any template pattern to alter its
5421     behavior.  For example, <literal>FM9999</literal>
5422     is the <literal>9999</literal> pattern with the
5423     <literal>FM</literal> modifier.
5424     <xref linkend="functions-formatting-numericmod-table"> shows the
5425     modifier patterns for numeric formatting.
5426    </para>
5427
5428     <table id="functions-formatting-numericmod-table">
5429      <title>Template Pattern Modifiers for Numeric Formatting</title>
5430      <tgroup cols="3">
5431       <thead>
5432        <row>
5433         <entry>Modifier</entry>
5434         <entry>Description</entry>
5435         <entry>Example</entry>
5436        </row>
5437       </thead>
5438       <tbody>
5439        <row>
5440         <entry><literal>FM</literal> prefix</entry>
5441         <entry>fill mode (suppress padding blanks and zeroes)</entry>
5442         <entry><literal>FM9999</literal></entry>
5443        </row>
5444        <row>
5445         <entry><literal>TH</literal> suffix</entry>
5446         <entry>uppercase ordinal number suffix</entry>
5447         <entry><literal>999TH</literal></entry>
5448        </row>   
5449        <row>
5450         <entry><literal>th</literal> suffix</entry>
5451         <entry>lowercase ordinal number suffix</entry>
5452         <entry><literal>999th</literal></entry>
5453        </row>
5454       </tbody>
5455      </tgroup>
5456     </table>
5457
5458   <para>
5459    <xref linkend="functions-formatting-examples-table"> shows some
5460    examples of the use of the <function>to_char</function> function.
5461   </para>
5462
5463     <table id="functions-formatting-examples-table">
5464      <title><function>to_char</function> Examples</title>
5465      <tgroup cols="2">
5466       <thead>
5467        <row>
5468         <entry>Expression</entry>
5469         <entry>Result</entry>
5470        </row>
5471       </thead>
5472       <tbody>
5473        <row>
5474         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5475         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
5476        </row>
5477        <row>
5478         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5479         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
5480        </row>          
5481        <row>
5482         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5483         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
5484        </row>
5485        <row>
5486         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5487         <entry><literal>'-.1'</literal></entry>
5488        </row>
5489        <row>
5490         <entry><literal>to_char(0.1, '0.9')</literal></entry>
5491         <entry><literal>'&nbsp;0.1'</literal></entry>
5492        </row>
5493        <row>
5494         <entry><literal>to_char(12, '9990999.9')</literal></entry>
5495         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
5496        </row>
5497        <row>
5498         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5499         <entry><literal>'0012.'</literal></entry>
5500        </row>
5501        <row>
5502         <entry><literal>to_char(485, '999')</literal></entry>
5503         <entry><literal>'&nbsp;485'</literal></entry>
5504        </row>
5505        <row>
5506         <entry><literal>to_char(-485, '999')</literal></entry>
5507         <entry><literal>'-485'</literal></entry>
5508        </row>
5509        <row>
5510         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
5511         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
5512        </row>
5513        <row>
5514         <entry><literal>to_char(1485, '9,999')</literal></entry>
5515         <entry><literal>'&nbsp;1,485'</literal></entry>
5516        </row>
5517        <row>
5518         <entry><literal>to_char(1485, '9G999')</literal></entry>
5519         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
5520        </row>
5521        <row>
5522         <entry><literal>to_char(148.5, '999.999')</literal></entry>
5523         <entry><literal>'&nbsp;148.500'</literal></entry>
5524        </row>
5525        <row>
5526         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5527         <entry><literal>'148.5'</literal></entry>
5528        </row>
5529        <row>
5530         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5531         <entry><literal>'148.500'</literal></entry>
5532        </row>
5533        <row>
5534         <entry><literal>to_char(148.5, '999D999')</literal></entry>
5535         <entry><literal>'&nbsp;148,500'</literal></entry>        
5536        </row>
5537        <row>
5538         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5539         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
5540        </row>
5541        <row>
5542         <entry><literal>to_char(-485, '999S')</literal></entry>
5543         <entry><literal>'485-'</literal></entry>
5544        </row>
5545        <row>            
5546         <entry><literal>to_char(-485, '999MI')</literal></entry>
5547         <entry><literal>'485-'</literal></entry>        
5548        </row>
5549        <row>
5550         <entry><literal>to_char(485, '999MI')</literal></entry>
5551         <entry><literal>'485&nbsp;'</literal></entry>           
5552        </row>
5553        <row>
5554         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5555         <entry><literal>'485'</literal></entry>         
5556        </row>
5557        <row>
5558         <entry><literal>to_char(485, 'PL999')</literal></entry>
5559         <entry><literal>'+485'</literal></entry>        
5560        </row>
5561        <row>            
5562         <entry><literal>to_char(485, 'SG999')</literal></entry>
5563         <entry><literal>'+485'</literal></entry>        
5564        </row>
5565        <row>
5566         <entry><literal>to_char(-485, 'SG999')</literal></entry>
5567         <entry><literal>'-485'</literal></entry>        
5568        </row>
5569        <row>
5570         <entry><literal>to_char(-485, '9SG99')</literal></entry>
5571         <entry><literal>'4-85'</literal></entry>        
5572        </row>
5573        <row>
5574         <entry><literal>to_char(-485, '999PR')</literal></entry>
5575         <entry><literal>'&lt;485&gt;'</literal></entry>         
5576        </row>
5577        <row>
5578         <entry><literal>to_char(485, 'L999')</literal></entry>
5579         <entry><literal>'DM&nbsp;485</literal></entry>   
5580        </row>
5581        <row>
5582         <entry><literal>to_char(485, 'RN')</literal></entry>            
5583         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
5584        </row>
5585        <row>
5586         <entry><literal>to_char(485, 'FMRN')</literal></entry>  
5587         <entry><literal>'CDLXXXV'</literal></entry>
5588        </row>
5589        <row>
5590         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5591         <entry><literal>'V'</literal></entry>           
5592        </row>
5593        <row>
5594         <entry><literal>to_char(482, '999th')</literal></entry>
5595         <entry><literal>'&nbsp;482nd'</literal></entry>                         
5596        </row>
5597        <row>
5598         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
5599         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
5600        </row>
5601        <row>
5602         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
5603         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
5604        </row>
5605        <row>
5606         <entry><literal>to_char(12, '99V999')</literal></entry>         
5607         <entry><literal>'&nbsp;12000'</literal></entry>
5608        </row>
5609        <row>
5610         <entry><literal>to_char(12.4, '99V999')</literal></entry>
5611         <entry><literal>'&nbsp;12400'</literal></entry>
5612        </row>
5613        <row>            
5614         <entry><literal>to_char(12.45, '99V9')</literal></entry>
5615         <entry><literal>'&nbsp;125'</literal></entry>
5616        </row>
5617        <row>
5618         <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
5619         <entry><literal>' 4.86e-04'</literal></entry>
5620        </row>
5621       </tbody>
5622      </tgroup>
5623     </table>
5624
5625   </sect1>
5626
5627
5628   <sect1 id="functions-datetime">
5629    <title>Date/Time Functions and Operators</title>
5630
5631   <para>
5632    <xref linkend="functions-datetime-table"> shows the available
5633    functions for date/time value processing, with details appearing in
5634    the following subsections.  <xref
5635    linkend="operators-datetime-table"> illustrates the behaviors of
5636    the basic arithmetic operators (<literal>+</literal>,
5637    <literal>*</literal>, etc.).  For formatting functions, refer to
5638    <xref linkend="functions-formatting">.  You should be familiar with
5639    the background information on date/time data types from <xref
5640    linkend="datatype-datetime">.
5641   </para>
5642
5643   <para>
5644    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
5645    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
5646    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
5647    For brevity, these variants are not shown separately.  Also, the
5648    <literal>+</> and <literal>*</> operators come in commutative pairs (for
5649    example both date + integer and integer + date); we show only one of each
5650    such pair.
5651   </para>
5652
5653     <table id="operators-datetime-table">
5654      <title>Date/Time Operators</title>
5655
5656      <tgroup cols="3">
5657       <thead>
5658        <row>
5659         <entry>Operator</entry>
5660         <entry>Example</entry>
5661         <entry>Result</entry>
5662        </row>
5663       </thead>
5664
5665       <tbody>
5666        <row>
5667         <entry> <literal>+</literal> </entry>
5668         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
5669         <entry><literal>date '2001-10-05'</literal></entry>
5670        </row>
5671
5672        <row>
5673         <entry> <literal>+</literal> </entry>
5674         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
5675         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
5676        </row>
5677
5678        <row>
5679         <entry> <literal>+</literal> </entry>
5680         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
5681         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
5682        </row>
5683
5684        <row>
5685         <entry> <literal>+</literal> </entry>
5686         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
5687         <entry><literal>interval '1 day 01:00:00'</literal></entry>
5688        </row>
5689
5690        <row>
5691         <entry> <literal>+</literal> </entry>
5692         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
5693         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
5694        </row>
5695
5696        <row>
5697         <entry> <literal>+</literal> </entry>
5698         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
5699         <entry><literal>time '04:00:00'</literal></entry>
5700        </row>
5701
5702        <row>
5703         <entry> <literal>-</literal> </entry>
5704         <entry><literal>- interval '23 hours'</literal></entry>
5705         <entry><literal>interval '-23:00:00'</literal></entry>
5706        </row>
5707
5708        <row>
5709         <entry> <literal>-</literal> </entry>
5710         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
5711         <entry><literal>integer '3'</literal> (days)</entry>
5712        </row>
5713
5714        <row>
5715         <entry> <literal>-</literal> </entry>
5716         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
5717         <entry><literal>date '2001-09-24'</literal></entry>
5718        </row>
5719
5720        <row>
5721         <entry> <literal>-</literal> </entry>
5722         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
5723         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
5724        </row>
5725
5726        <row>
5727         <entry> <literal>-</literal> </entry>
5728         <entry><literal>time '05:00' - time '03:00'</literal></entry>
5729         <entry><literal>interval '02:00:00'</literal></entry>
5730        </row>
5731
5732        <row>
5733         <entry> <literal>-</literal> </entry>
5734         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
5735         <entry><literal>time '03:00:00'</literal></entry>
5736        </row>
5737
5738        <row>
5739         <entry> <literal>-</literal> </entry>
5740         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
5741         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
5742        </row>
5743
5744        <row>
5745         <entry> <literal>-</literal> </entry>
5746         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
5747         <entry><literal>interval '1 day -01:00:00'</literal></entry>
5748        </row>
5749
5750        <row>
5751         <entry> <literal>-</literal> </entry>
5752         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
5753         <entry><literal>interval '1 day 15:00:00'</literal></entry>
5754        </row>
5755
5756        <row>
5757         <entry> <literal>*</literal> </entry>
5758         <entry><literal>900 * interval '1 second'</literal></entry>
5759         <entry><literal>interval '00:15:00'</literal></entry>
5760        </row>
5761
5762        <row>
5763         <entry> <literal>*</literal> </entry>
5764         <entry><literal>21 * interval '1 day'</literal></entry>
5765         <entry><literal>interval '21 days'</literal></entry>
5766        </row>
5767
5768        <row>
5769         <entry> <literal>*</literal> </entry>
5770         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
5771         <entry><literal>interval '03:30:00'</literal></entry>
5772        </row>
5773
5774        <row>
5775         <entry> <literal>/</literal> </entry>
5776         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
5777         <entry><literal>interval '00:40:00'</literal></entry>
5778        </row>
5779       </tbody>
5780      </tgroup>
5781     </table>
5782
5783    <indexterm>
5784     <primary>age</primary>
5785    </indexterm>
5786    <indexterm>
5787     <primary>clock_timestamp</primary>
5788    </indexterm>
5789    <indexterm>
5790     <primary>current_date</primary>
5791    </indexterm>
5792    <indexterm>
5793     <primary>current_time</primary>
5794    </indexterm>
5795    <indexterm>
5796     <primary>current_timestamp</primary>
5797    </indexterm>
5798    <indexterm>
5799     <primary>date_part</primary>
5800    </indexterm>
5801    <indexterm>
5802     <primary>date_trunc</primary>
5803    </indexterm>
5804    <indexterm>
5805     <primary>extract</primary>
5806    </indexterm>
5807    <indexterm>
5808     <primary>isfinite</primary>
5809    </indexterm>
5810    <indexterm>
5811     <primary>justify_days</primary>
5812    </indexterm>
5813    <indexterm>
5814     <primary>justify_hours</primary>
5815    </indexterm>
5816    <indexterm>
5817     <primary>justify_interval</primary>
5818    </indexterm>
5819    <indexterm>
5820     <primary>localtime</primary>
5821    </indexterm>
5822    <indexterm>
5823     <primary>localtimestamp</primary>
5824    </indexterm>
5825    <indexterm>
5826     <primary>now</primary>
5827    </indexterm>
5828    <indexterm>
5829     <primary>statement_timestamp</primary>
5830    </indexterm>
5831    <indexterm>
5832     <primary>timeofday</primary>
5833    </indexterm>
5834    <indexterm>
5835     <primary>transaction_timestamp</primary>
5836    </indexterm>
5837
5838     <table id="functions-datetime-table">
5839      <title>Date/Time Functions</title>
5840      <tgroup cols="5">
5841       <thead>
5842        <row>
5843         <entry>Function</entry>
5844         <entry>Return Type</entry>
5845         <entry>Description</entry>
5846         <entry>Example</entry>
5847         <entry>Result</entry>
5848        </row>
5849       </thead>
5850
5851       <tbody>
5852        <row>
5853         <entry><literal><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</literal></entry>
5854         <entry><type>interval</type></entry>
5855         <entry>Subtract arguments, producing a <quote>symbolic</> result that
5856         uses years and months</entry>
5857         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
5858         <entry><literal>43 years 9 mons 27 days</literal></entry>
5859        </row>
5860
5861        <row>
5862         <entry><literal><function>age</function>(<type>timestamp</type>)</literal></entry>
5863         <entry><type>interval</type></entry>
5864         <entry>Subtract from <function>current_date</function> (at midnight)</entry>
5865         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
5866         <entry><literal>43 years 8 mons 3 days</literal></entry>
5867        </row>
5868
5869        <row>
5870         <entry><literal><function>clock_timestamp</function>()</literal></entry>
5871         <entry><type>timestamp with time zone</type></entry>
5872         <entry>Current date and time (changes during statement execution);
5873          see <xref linkend="functions-datetime-current">
5874         </entry>
5875         <entry></entry>
5876         <entry></entry>
5877        </row>
5878
5879        <row>
5880         <entry><literal><function>current_date</function></literal></entry>
5881         <entry><type>date</type></entry>
5882         <entry>Current date;
5883          see <xref linkend="functions-datetime-current">
5884         </entry>
5885         <entry></entry>
5886         <entry></entry>
5887        </row>
5888
5889        <row>
5890         <entry><literal><function>current_time</function></literal></entry>
5891         <entry><type>time with time zone</type></entry>
5892         <entry>Current time of day;
5893          see <xref linkend="functions-datetime-current">
5894         </entry>
5895         <entry></entry>
5896         <entry></entry>
5897        </row>
5898
5899        <row>
5900         <entry><literal><function>current_timestamp</function></literal></entry>
5901         <entry><type>timestamp with time zone</type></entry>
5902         <entry>Current date and time (start of current transaction);
5903          see <xref linkend="functions-datetime-current">
5904         </entry>
5905         <entry></entry>
5906         <entry></entry>
5907        </row>
5908
5909        <row>
5910         <entry><literal><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5911         <entry><type>double precision</type></entry>
5912         <entry>Get subfield (equivalent to <function>extract</function>);
5913          see <xref linkend="functions-datetime-extract">
5914         </entry>
5915         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5916         <entry><literal>20</literal></entry>
5917        </row>
5918
5919        <row>
5920         <entry><literal><function>date_part</function>(<type>text</type>, <type>interval</type>)</literal></entry>
5921         <entry><type>double precision</type></entry>
5922         <entry>Get subfield (equivalent to
5923          <function>extract</function>); see <xref linkend="functions-datetime-extract">
5924         </entry>
5925         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
5926         <entry><literal>3</literal></entry>
5927        </row>
5928
5929        <row>
5930         <entry><literal><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5931         <entry><type>timestamp</type></entry>
5932         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
5933         </entry>
5934         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5935         <entry><literal>2001-02-16 20:00:00</literal></entry>
5936        </row>
5937
5938        <row>
5939         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5940          <type>timestamp</type>)</literal></entry>
5941         <entry><type>double precision</type></entry>
5942         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5943         </entry>
5944         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
5945         <entry><literal>20</literal></entry>
5946        </row>
5947
5948        <row>
5949         <entry><literal><function>extract</function>(<parameter>field</parameter> from
5950          <type>interval</type>)</literal></entry>
5951         <entry><type>double precision</type></entry>
5952         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5953         </entry>
5954         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
5955         <entry><literal>3</literal></entry>
5956        </row>
5957
5958        <row>
5959         <entry><literal><function>isfinite</function>(<type>date</type>)</literal></entry>
5960         <entry><type>boolean</type></entry>
5961         <entry>Test for finite date (not +/-infinity)</entry>
5962         <entry><literal>isfinite(date '2001-02-16')</literal></entry>
5963         <entry><literal>true</literal></entry>
5964        </row>
5965
5966        <row>
5967         <entry><literal><function>isfinite</function>(<type>timestamp</type>)</literal></entry>
5968         <entry><type>boolean</type></entry>
5969         <entry>Test for finite time stamp (not +/-infinity)</entry>
5970         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
5971         <entry><literal>true</literal></entry>
5972        </row>
5973
5974        <row>
5975         <entry><literal><function>isfinite</function>(<type>interval</type>)</literal></entry>
5976         <entry><type>boolean</type></entry>
5977         <entry>Test for finite interval</entry>
5978         <entry><literal>isfinite(interval '4 hours')</literal></entry>
5979         <entry><literal>true</literal></entry>
5980        </row>
5981
5982        <row>
5983         <entry><literal><function>justify_days</function>(<type>interval</type>)</literal></entry>
5984         <entry><type>interval</type></entry>
5985         <entry>Adjust interval so 30-day time periods are represented as months</entry>
5986         <entry><literal>justify_days(interval '35 days')</literal></entry>
5987         <entry><literal>1 mon 5 days</literal></entry>
5988        </row>
5989
5990        <row>
5991         <entry><literal><function>justify_hours</function>(<type>interval</type>)</literal></entry>
5992         <entry><type>interval</type></entry>
5993         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
5994         <entry><literal>justify_hours(interval '27 hours')</literal></entry>
5995         <entry><literal>1 day 03:00:00</literal></entry>
5996        </row>
5997
5998        <row>
5999         <entry><literal><function>justify_interval</function>(<type>interval</type>)</literal></entry>
6000         <entry><type>interval</type></entry>
6001         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
6002         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
6003         <entry><literal>29 days 23:00:00</literal></entry>
6004        </row>
6005
6006        <row>
6007         <entry><literal><function>localtime</function></literal></entry>
6008         <entry><type>time</type></entry>
6009         <entry>Current time of day;
6010          see <xref linkend="functions-datetime-current">
6011         </entry>
6012         <entry></entry>
6013         <entry></entry>
6014        </row>
6015
6016        <row>
6017         <entry><literal><function>localtimestamp</function></literal></entry>
6018         <entry><type>timestamp</type></entry>
6019         <entry>Current date and time (start of current transaction);
6020          see <xref linkend="functions-datetime-current">
6021         </entry>
6022         <entry></entry>
6023         <entry></entry>
6024        </row>
6025
6026        <row>
6027         <entry><literal><function>now</function>()</literal></entry>
6028         <entry><type>timestamp with time zone</type></entry>
6029         <entry>Current date and time (start of current transaction);
6030          see <xref linkend="functions-datetime-current">
6031         </entry>
6032         <entry></entry>
6033         <entry></entry>
6034        </row>
6035
6036        <row>
6037         <entry><literal><function>statement_timestamp</function>()</literal></entry>
6038         <entry><type>timestamp with time zone</type></entry>
6039         <entry>Current date and time (start of current statement);
6040          see <xref linkend="functions-datetime-current">
6041         </entry>
6042         <entry></entry>
6043         <entry></entry>
6044        </row>
6045
6046        <row>
6047         <entry><literal><function>timeofday</function>()</literal></entry>
6048         <entry><type>text</type></entry>
6049         <entry>Current date and time
6050          (like <function>clock_timestamp</>, but as a <type>text</> string);
6051          see <xref linkend="functions-datetime-current">
6052         </entry>
6053         <entry></entry>
6054         <entry></entry>
6055        </row>
6056
6057        <row>
6058         <entry><literal><function>transaction_timestamp</function>()</literal></entry>
6059         <entry><type>timestamp with time zone</type></entry>
6060         <entry>Current date and time (start of current transaction);
6061          see <xref linkend="functions-datetime-current">
6062         </entry>
6063         <entry></entry>
6064         <entry></entry>
6065        </row>
6066       </tbody>
6067      </tgroup>
6068     </table>
6069
6070    <para>
6071     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6072     supported:
6073 <synopsis>
6074 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6075 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6076 </synopsis>
6077     This expression yields true when two time periods (defined by their
6078     endpoints) overlap, false when they do not overlap.  The endpoints
6079     can be specified as pairs of dates, times, or time stamps; or as
6080     a date, time, or time stamp followed by an interval.
6081    </para>
6082
6083 <screen>
6084 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6085        (DATE '2001-10-30', DATE '2002-10-30');
6086 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6087 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6088        (DATE '2001-10-30', DATE '2002-10-30');
6089 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6090 </screen>
6091
6092   <para>
6093    When adding an <type>interval</type> value to (or subtracting an 
6094    <type>interval</type> value from) a <type>timestamp with time zone</type> 
6095    value, the days component advances (or decrements) the date of the 
6096    <type>timestamp with time zone</type> by the indicated number of days. 
6097    Across daylight saving time changes (with the session time zone set to a 
6098    time zone that recognizes DST), this means <literal>interval '1 day'</literal> 
6099    does not necessarily equal <literal>interval '24 hours'</literal>. 
6100    For example, with the session time zone set to <literal>CST7CDT</literal>,
6101    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
6102    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>, 
6103    while adding <literal>interval '24 hours'</literal> to the same initial 
6104    <type>timestamp with time zone</type> produces
6105    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6106    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone 
6107    <literal>CST7CDT</literal>.
6108   </para>
6109
6110   <para>
6111    Note there can be ambiguity in the <literal>months</> returned by
6112    <function>age</> because different months have a different number of
6113    days.  <productname>PostgreSQL</>'s approach uses the month from the
6114    earlier of the two dates when calculating partial months.  For example,
6115    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6116    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6117    days</> because May has 31 days, while April has only 30.
6118   </para>
6119
6120   <sect2 id="functions-datetime-extract">
6121    <title><function>EXTRACT</function>, <function>date_part</function></title>
6122
6123    <indexterm>
6124     <primary>date_part</primary>
6125    </indexterm>
6126    <indexterm>
6127     <primary>extract</primary>
6128    </indexterm>
6129
6130 <synopsis>
6131 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6132 </synopsis>
6133
6134    <para>
6135     The <function>extract</function> function retrieves subfields
6136     such as year or hour from date/time values.
6137     <replaceable>source</replaceable> must be a value expression of
6138     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6139     (Expressions of type <type>date</type> are
6140     cast to <type>timestamp</type> and can therefore be used as
6141     well.)  <replaceable>field</replaceable> is an identifier or
6142     string that selects what field to extract from the source value.
6143     The <function>extract</function> function returns values of type
6144     <type>double precision</type>.
6145     The following are valid field names:
6146
6147     <!-- alphabetical -->
6148     <variablelist>
6149      <varlistentry>
6150       <term><literal>century</literal></term>
6151       <listitem>
6152        <para>
6153         The century
6154        </para>
6155
6156 <screen>
6157 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6158 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6159 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6160 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6161 </screen>
6162
6163        <para>
6164         The first century starts at 0001-01-01 00:00:00 AD, although
6165         they did not know it at the time. This definition applies to all
6166         Gregorian calendar countries. There is no century number 0,
6167         you go from -1 century to 1 century.
6168
6169         If you disagree with this, please write your complaint to:
6170         Pope, Cathedral Saint-Peter of Roma, Vatican.
6171        </para>
6172
6173        <para>
6174         <productname>PostgreSQL</productname> releases before 8.0 did not
6175         follow the conventional numbering of centuries, but just returned
6176         the year field divided by 100.
6177        </para>
6178       </listitem>
6179      </varlistentry>
6180
6181      <varlistentry>
6182       <term><literal>day</literal></term>
6183       <listitem>
6184        <para>
6185         The day (of the month) field (1 - 31)
6186        </para>
6187
6188 <screen>
6189 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6190 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6191 </screen>
6192       </listitem>
6193      </varlistentry>
6194
6195      <varlistentry>
6196       <term><literal>decade</literal></term>
6197       <listitem>
6198        <para>
6199         The year field divided by 10
6200        </para>
6201
6202 <screen>
6203 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6204 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6205 </screen>
6206       </listitem>
6207      </varlistentry>
6208
6209      <varlistentry>
6210       <term><literal>dow</literal></term>
6211       <listitem>
6212        <para>
6213         The day of the week as Sunday(<literal>0</>) to
6214         Saturday(<literal>6</>)
6215        </para>
6216
6217 <screen>
6218 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6219 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6220 </screen>
6221        <para>
6222         Note that <function>extract</function>'s day of the week numbering
6223         differs from that of the <function>to_char(...,
6224         'D')</function> function.
6225        </para>
6226
6227       </listitem>
6228      </varlistentry>
6229
6230      <varlistentry>
6231       <term><literal>doy</literal></term>
6232       <listitem>
6233        <para>
6234         The day of the year (1 - 365/366)
6235        </para>
6236
6237 <screen>
6238 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6239 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6240 </screen>
6241       </listitem>
6242      </varlistentry>
6243
6244      <varlistentry>
6245       <term><literal>epoch</literal></term>
6246       <listitem>
6247        <para>
6248         For <type>date</type> and <type>timestamp</type> values, the
6249         number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
6250         for <type>interval</type> values, the total number
6251         of seconds in the interval
6252        </para>
6253
6254 <screen>
6255 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
6256 <lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput>
6257
6258 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6259 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6260 </screen>
6261
6262        <para>
6263         Here is how you can convert an epoch value back to a time
6264         stamp:
6265        </para>
6266 <screen>
6267 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second';
6268 </screen>
6269        <para>
6270         (The <function>to_timestamp</> function encapsulates the above
6271         conversion.)
6272        </para>
6273       </listitem>
6274      </varlistentry>
6275
6276      <varlistentry>
6277       <term><literal>hour</literal></term>
6278       <listitem>
6279        <para>
6280         The hour field (0 - 23)
6281        </para>
6282
6283 <screen>
6284 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6285 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6286 </screen>
6287       </listitem>
6288      </varlistentry>
6289
6290      <varlistentry>
6291       <term><literal>isodow</literal></term>
6292       <listitem>
6293        <para>
6294         The day of the week as Monday(<literal>1</>) to
6295         Sunday(<literal>7</>)
6296        </para>
6297
6298 <screen>
6299 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6300 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6301 </screen>
6302        <para>
6303         This is identical to <literal>dow</> except for Sunday.  This
6304         matches the <acronym>ISO</> 8601 day of the week numbering.
6305        </para>
6306
6307       </listitem>
6308      </varlistentry>
6309
6310      <varlistentry>
6311       <term><literal>isoyear</literal></term>
6312       <listitem>
6313        <para>
6314         The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals)
6315        </para>
6316
6317 <screen>
6318 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6319 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6320 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6321 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6322 </screen>
6323
6324        <para>
6325         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.
6326        </para>
6327        <para>
6328         This field is not available in PostgreSQL releases prior to 8.3.
6329        </para>
6330       </listitem>
6331      </varlistentry>
6332
6333      <varlistentry>
6334       <term><literal>microseconds</literal></term>
6335       <listitem>
6336        <para>
6337         The seconds field, including fractional parts, multiplied by 1
6338         000 000;  note that this includes full seconds
6339        </para>
6340
6341 <screen>
6342 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6343 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6344 </screen>
6345       </listitem>
6346      </varlistentry>
6347
6348      <varlistentry>
6349       <term><literal>millennium</literal></term>
6350       <listitem>
6351        <para>
6352         The millennium
6353        </para>
6354
6355 <screen>
6356 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6357 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6358 </screen>
6359
6360        <para>
6361         Years in the 1900s are in the second millennium.
6362         The third millennium started January 1, 2001.
6363        </para>
6364
6365        <para>
6366         <productname>PostgreSQL</productname> releases before 8.0 did not
6367         follow the conventional numbering of millennia, but just returned
6368         the year field divided by 1000.
6369        </para>
6370       </listitem>
6371      </varlistentry>
6372
6373      <varlistentry>
6374       <term><literal>milliseconds</literal></term>
6375       <listitem>
6376        <para>
6377         The seconds field, including fractional parts, multiplied by
6378         1000.  Note that this includes full seconds.
6379        </para>
6380
6381 <screen>
6382 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6383 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6384 </screen>
6385       </listitem>
6386      </varlistentry>
6387
6388      <varlistentry>
6389       <term><literal>minute</literal></term>
6390       <listitem>
6391        <para>
6392         The minutes field (0 - 59)
6393        </para>
6394
6395 <screen>
6396 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6397 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6398 </screen>
6399       </listitem>
6400      </varlistentry>
6401
6402      <varlistentry>
6403       <term><literal>month</literal></term>
6404       <listitem>
6405        <para>
6406         For <type>timestamp</type> values, the number of the month
6407         within the year (1 - 12) ; for <type>interval</type> values
6408         the number of months, modulo 12 (0 - 11)
6409        </para>
6410
6411 <screen>
6412 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6413 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6414
6415 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6416 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6417
6418 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6419 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6420 </screen>
6421       </listitem>
6422      </varlistentry>
6423
6424      <varlistentry>
6425       <term><literal>quarter</literal></term>
6426       <listitem>
6427        <para>
6428         The quarter of the year (1 - 4) that the date is in
6429        </para>
6430
6431 <screen>
6432 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6433 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6434 </screen>
6435       </listitem>
6436      </varlistentry>
6437
6438      <varlistentry>
6439       <term><literal>second</literal></term>
6440       <listitem>
6441        <para>
6442         The seconds field, including fractional parts (0 -
6443         59<footnote><simpara>60 if leap seconds are
6444         implemented by the operating system</simpara></footnote>)
6445        </para>
6446
6447 <screen>
6448 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6449 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6450
6451 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6452 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6453 </screen>
6454       </listitem>
6455      </varlistentry>
6456      <varlistentry>
6457       <term><literal>timezone</literal></term>
6458       <listitem>
6459        <para>
6460         The time zone offset from UTC, measured in seconds.  Positive values
6461         correspond to time zones east of UTC, negative values to
6462         zones west of UTC.
6463        </para>
6464       </listitem>
6465      </varlistentry>
6466
6467      <varlistentry>
6468       <term><literal>timezone_hour</literal></term>
6469       <listitem>
6470        <para>
6471         The hour component of the time zone offset
6472        </para>
6473       </listitem>
6474      </varlistentry>
6475
6476      <varlistentry>
6477       <term><literal>timezone_minute</literal></term>
6478       <listitem>
6479        <para>
6480         The minute component of the time zone offset
6481        </para>
6482       </listitem>
6483      </varlistentry>
6484
6485      <varlistentry>
6486       <term><literal>week</literal></term>
6487       <listitem>
6488        <para>
6489         The number of the week of the year that the day is in.  By definition
6490         (<acronym>ISO</acronym> 8601), the first week of a year
6491         contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
6492         week starts on Monday.)  In other words, the first Thursday of
6493         a year is in week 1 of that year.
6494        </para>
6495        <para>
6496         Because of this, it is possible for early January dates to be part of the 
6497         52nd or 53rd week of the previous year.  For example, <literal>2005-01-01</>
6498         is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of 
6499         the 52nd week of year 2005.
6500        </para>
6501
6502 <screen>
6503 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6504 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6505 </screen>
6506       </listitem>
6507      </varlistentry>
6508
6509      <varlistentry>
6510       <term><literal>year</literal></term>
6511       <listitem>
6512        <para>
6513         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting 
6514         <literal>BC</> years from <literal>AD</> years should be done with care.
6515        </para>
6516
6517 <screen>
6518 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6519 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6520 </screen>
6521       </listitem>
6522      </varlistentry>
6523
6524     </variablelist>
6525    </para>
6526
6527    <para>
6528     The <function>extract</function> function is primarily intended
6529     for computational processing.  For formatting date/time values for
6530     display, see <xref linkend="functions-formatting">.
6531    </para>
6532
6533    <para>
6534     The <function>date_part</function> function is modeled on the traditional
6535     <productname>Ingres</productname> equivalent to the
6536     <acronym>SQL</acronym>-standard function <function>extract</function>:
6537 <synopsis>
6538 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6539 </synopsis>
6540     Note that here the <replaceable>field</replaceable> parameter needs to
6541     be a string value, not a name.  The valid field names for
6542     <function>date_part</function> are the same as for
6543     <function>extract</function>.
6544    </para>
6545
6546 <screen>
6547 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
6548 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6549
6550 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
6551 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
6552 </screen>
6553
6554   </sect2>
6555
6556   <sect2 id="functions-datetime-trunc">
6557    <title><function>date_trunc</function></title>
6558
6559    <indexterm>
6560     <primary>date_trunc</primary>
6561    </indexterm>
6562
6563    <para>
6564     The function <function>date_trunc</function> is conceptually
6565     similar to the <function>trunc</function> function for numbers.
6566    </para>
6567
6568    <para>
6569 <synopsis>
6570 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6571 </synopsis>
6572     <replaceable>source</replaceable> is a value expression of type
6573     <type>timestamp</type> or <type>interval</>.
6574     (Values of type <type>date</type> and
6575     <type>time</type> are cast automatically to <type>timestamp</type> or
6576     <type>interval</>, respectively.)
6577     <replaceable>field</replaceable> selects to which precision to
6578     truncate the input value.  The return value is of type
6579     <type>timestamp</type> or <type>interval</>
6580     with all fields that are less significant than the
6581     selected one set to zero (or one, for day and month).
6582    </para>
6583
6584    <para>
6585     Valid values for <replaceable>field</replaceable> are:
6586     <simplelist>
6587      <member><literal>microseconds</literal></member>
6588      <member><literal>milliseconds</literal></member>
6589      <member><literal>second</literal></member>
6590      <member><literal>minute</literal></member>
6591      <member><literal>hour</literal></member>
6592      <member><literal>day</literal></member>
6593      <member><literal>week</literal></member>
6594      <member><literal>month</literal></member>
6595      <member><literal>quarter</literal></member>
6596      <member><literal>year</literal></member>
6597      <member><literal>decade</literal></member>
6598      <member><literal>century</literal></member>
6599      <member><literal>millennium</literal></member>
6600     </simplelist>
6601    </para>
6602
6603    <para>
6604     Examples:
6605 <screen>
6606 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
6607 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
6608
6609 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
6610 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
6611 </screen>
6612    </para>
6613   </sect2>
6614
6615   <sect2 id="functions-datetime-zoneconvert">
6616    <title><literal>AT TIME ZONE</literal></title>
6617
6618    <indexterm>
6619     <primary>time zone</primary>
6620     <secondary>conversion</secondary>
6621    </indexterm>
6622
6623    <indexterm>
6624     <primary>AT TIME ZONE</primary>
6625    </indexterm>
6626
6627    <para>
6628     The <literal>AT TIME ZONE</literal> construct allows conversions
6629     of time stamps to different time zones.  <xref
6630     linkend="functions-datetime-zoneconvert-table"> shows its
6631     variants.
6632    </para>
6633
6634     <table id="functions-datetime-zoneconvert-table">
6635      <title><literal>AT TIME ZONE</literal> Variants</title>
6636      <tgroup cols="3">
6637       <thead>
6638        <row>
6639         <entry>Expression</entry>
6640         <entry>Return Type</entry>
6641         <entry>Description</entry>
6642        </row>
6643       </thead>
6644
6645       <tbody>
6646        <row>
6647         <entry>
6648          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6649         </entry>
6650         <entry><type>timestamp with time zone</type></entry>
6651         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
6652        </row>
6653
6654        <row>
6655         <entry>
6656          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6657         </entry>
6658         <entry><type>timestamp without time zone</type></entry>
6659         <entry>Convert given time stamp <emphasis>with time zone</> to the new time
6660         zone, with no time zone designation</entry>
6661        </row>
6662
6663        <row>
6664         <entry>
6665          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6666         </entry>
6667         <entry><type>time with time zone</type></entry>
6668         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
6669        </row>
6670       </tbody>
6671      </tgroup>
6672     </table>
6673
6674    <para>
6675     In these expressions, the desired time zone <replaceable>zone</> can be
6676     specified either as a text string (e.g., <literal>'PST'</literal>)
6677     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
6678     In the text case, a time zone name can be specified in any of the ways
6679     described in <xref linkend="datatype-timezones">.
6680    </para>
6681
6682    <para>
6683     Examples (assuming the local time zone is <literal>PST8PDT</>):
6684 <screen>
6685 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
6686 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
6687
6688 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
6689 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
6690 </screen>
6691     The first example takes a time stamp without time zone and interprets it as MST time
6692     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes 
6693     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
6694    </para>
6695
6696    <para>
6697     The function <literal><function>timezone</function>(<replaceable>zone</>,
6698     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
6699     <literal><replaceable>timestamp</> AT TIME ZONE
6700     <replaceable>zone</></literal>. 
6701    </para>
6702   </sect2>
6703
6704   <sect2 id="functions-datetime-current">
6705    <title>Current Date/Time</title>
6706
6707    <indexterm>
6708     <primary>date</primary>
6709     <secondary>current</secondary>
6710    </indexterm>
6711
6712    <indexterm>
6713     <primary>time</primary>
6714     <secondary>current</secondary>
6715    </indexterm>
6716
6717    <para>
6718     <productname>PostgreSQL</productname> provides a number of functions
6719     that return values related to the current date and time.  These
6720     SQL-standard functions all return values based on the start time of
6721     the current transaction:
6722 <synopsis>
6723 CURRENT_DATE
6724 CURRENT_TIME
6725 CURRENT_TIMESTAMP
6726 CURRENT_TIME(<replaceable>precision</replaceable>)
6727 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
6728 LOCALTIME
6729 LOCALTIMESTAMP
6730 LOCALTIME(<replaceable>precision</replaceable>)
6731 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
6732 </synopsis>
6733     </para>
6734
6735     <para>
6736      <function>CURRENT_TIME</function> and
6737      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
6738      <function>LOCALTIME</function> and
6739      <function>LOCALTIMESTAMP</function> deliver values without time zone.
6740     </para>
6741
6742     <para>
6743      <function>CURRENT_TIME</function>,
6744      <function>CURRENT_TIMESTAMP</function>,
6745      <function>LOCALTIME</function>, and
6746      <function>LOCALTIMESTAMP</function>
6747      can optionally take
6748      a precision parameter, which causes the result to be rounded
6749      to that many fractional digits in the seconds field.  Without a precision parameter,
6750      the result is given to the full available precision.
6751     </para>
6752
6753    <para>
6754     Some examples:
6755 <screen>
6756 SELECT CURRENT_TIME;
6757 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
6758
6759 SELECT CURRENT_DATE;
6760 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
6761
6762 SELECT CURRENT_TIMESTAMP;
6763 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
6764
6765 SELECT CURRENT_TIMESTAMP(2);
6766 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
6767
6768 SELECT LOCALTIMESTAMP;
6769 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
6770 </screen>
6771    </para>
6772
6773    <para>
6774     Since these functions return
6775     the start time of the current transaction, their values do not
6776     change during the transaction. This is considered a feature:
6777     the intent is to allow a single transaction to have a consistent
6778     notion of the <quote>current</quote> time, so that multiple
6779     modifications within the same transaction bear the same
6780     time stamp.
6781    </para>
6782
6783    <note>
6784     <para>
6785      Other database systems might advance these values more
6786      frequently.
6787     </para>
6788    </note>
6789
6790    <para>
6791     <productname>PostgreSQL</productname> also provides functions that
6792     return the start time of the current statement, as well as the actual
6793     current time at the instant the function is called.  The complete list
6794     of non-SQL-standard time functions is:
6795 <synopsis>
6796 transaction_timestamp()
6797 statement_timestamp()
6798 clock_timestamp()
6799 timeofday()
6800 now()
6801 </synopsis>
6802    </para>
6803
6804    <para>
6805     <function>transaction_timestamp()</> is equivalent to
6806     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
6807     what it returns.
6808     <function>statement_timestamp()</> returns the start time of the current
6809     statement (more specifically, the time of receipt of the latest command
6810     message from the client).
6811     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
6812     return the same value during the first command of a transaction, but might
6813     differ during subsequent commands.
6814     <function>clock_timestamp()</> returns the actual current time, and
6815     therefore its value changes even within a single SQL command.
6816     <function>timeofday()</> is a historical
6817     <productname>PostgreSQL</productname> function.  Like
6818     <function>clock_timestamp()</>, it returns the actual current time,
6819     but as a formatted <type>text</> string rather than a <type>timestamp
6820     with time zone</> value.
6821     <function>now()</> is a traditional <productname>PostgreSQL</productname>
6822     equivalent to <function>transaction_timestamp()</function>.
6823    </para>
6824
6825    <para>
6826     All the date/time data types also accept the special literal value
6827     <literal>now</literal> to specify the current date and time (again,
6828     interpreted as the transaction start time).  Thus,
6829     the following three all return the same result:
6830 <programlisting>
6831 SELECT CURRENT_TIMESTAMP;
6832 SELECT now();
6833 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
6834 </programlisting>
6835    </para>
6836
6837     <tip>
6838      <para>
6839       You do not want to use the third form when specifying a <literal>DEFAULT</>
6840       clause while creating a table.  The system will convert <literal>now</literal>
6841       to a <type>timestamp</type> as soon as the constant is parsed, so that when
6842       the default value is needed,
6843       the time of the table creation would be used!  The first two
6844       forms will not be evaluated until the default value is used,
6845       because they are function calls.  Thus they will give the desired
6846       behavior of defaulting to the time of row insertion.
6847      </para>
6848     </tip>
6849   </sect2>
6850
6851   <sect2 id="functions-datetime-delay">
6852    <title>Delaying Execution</title>
6853
6854    <indexterm>
6855     <primary>pg_sleep</primary>
6856    </indexterm>
6857    <indexterm>
6858     <primary>sleep</primary>
6859    </indexterm>
6860    <indexterm>
6861     <primary>delay</primary>
6862    </indexterm>
6863
6864    <para>
6865     The following function is available to delay execution of the server
6866     process:
6867 <synopsis>
6868 pg_sleep(<replaceable>seconds</replaceable>)
6869 </synopsis>
6870
6871     <function>pg_sleep</function> makes the current session's process
6872     sleep until <replaceable>seconds</replaceable> seconds have
6873     elapsed.  <replaceable>seconds</replaceable> is a value of type
6874     <type>double precision</>, so fractional-second delays can be specified.
6875     For example:
6876
6877 <programlisting>
6878 SELECT pg_sleep(1.5);
6879 </programlisting>
6880    </para>
6881
6882    <note>
6883      <para>
6884       The effective resolution of the sleep interval is platform-specific;
6885       0.01 seconds is a common value.  The sleep delay will be at least as long
6886       as specified. It might be longer depending on factors such as server load.
6887      </para>
6888    </note>
6889
6890    <warning>
6891      <para>
6892       Make sure that your session does not hold more locks than necessary
6893       when calling <function>pg_sleep</function>.  Otherwise other sessions
6894       might have to wait for your sleeping process, slowing down the entire
6895       system.
6896      </para>
6897    </warning>
6898   </sect2>
6899
6900  </sect1>
6901
6902   
6903  <sect1 id="functions-enum">
6904   <title>Enum Support Functions</title>
6905
6906   <para>
6907    For enum types (described in <xref linkend="datatype-enum">),
6908    there are several functions that allow cleaner programming without
6909    hard-coding particular values of an enum type.
6910    These are listed in <xref linkend="functions-enum-table">. The examples
6911    assume an enum type created as:
6912
6913 <programlisting>
6914 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
6915 </programlisting>
6916
6917   </para>
6918
6919   <table id="functions-enum-table">
6920     <title>Enum Support Functions</title>
6921     <tgroup cols="4">
6922      <thead>
6923       <row>
6924        <entry>Function</entry>
6925        <entry>Description</entry>
6926        <entry>Example</entry>
6927        <entry>Example Result</entry>
6928       </row>
6929      </thead>
6930      <tbody>
6931       <row>
6932        <entry><literal>enum_first(anyenum)</literal></entry>
6933        <entry>Returns the first value of the input enum type</entry>
6934        <entry><literal>enum_first(null::rainbow)</literal></entry>
6935        <entry><literal>red</literal></entry>
6936       </row>
6937       <row>
6938        <entry><literal>enum_last(anyenum)</literal></entry>
6939        <entry>Returns the last value of the input enum type</entry>
6940        <entry><literal>enum_last(null::rainbow)</literal></entry>
6941        <entry><literal>purple</literal></entry>
6942       </row>
6943       <row>
6944        <entry><literal>enum_range(anyenum)</literal></entry>
6945        <entry>Returns all values of the input enum type in an ordered array</entry>
6946        <entry><literal>enum_range(null::rainbow)</literal></entry>
6947        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
6948       </row>
6949       <row>
6950        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
6951        <entry morerows="2">
6952         Returns the range between the two given enum values, as an ordered
6953         array. The values must be from the same enum type. If the first
6954         parameter is null, the result will start with the first value of
6955         the enum type.
6956         If the second parameter is null, the result will end with the last
6957         value of the enum type.
6958        </entry>
6959        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
6960        <entry><literal>{orange,yellow,green}</literal></entry>
6961       </row>
6962       <row>
6963        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
6964        <entry><literal>{red,orange,yellow,green}</literal></entry>
6965       </row>
6966       <row>
6967        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
6968        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
6969       </row>
6970      </tbody>
6971     </tgroup>
6972    </table>
6973
6974    <para>
6975     Notice that except for the two-argument form of <function>enum_range</>,
6976     these functions disregard the specific value passed to them; they care
6977     only about its declared data type.  Either null or a specific value of
6978     the type can be passed, with the same result.  It is more common to
6979     apply these functions to a table column or function argument than to
6980     a hardwired type name as suggested by the examples.
6981    </para>
6982  </sect1>
6983
6984  <sect1 id="functions-geometry">
6985   <title>Geometric Functions and Operators</title>
6986
6987    <para>
6988     The geometric types <type>point</type>, <type>box</type>,
6989     <type>lseg</type>, <type>line</type>, <type>path</type>,
6990     <type>polygon</type>, and <type>circle</type> have a large set of
6991     native support functions and operators, shown in <xref
6992     linkend="functions-geometry-op-table">, <xref
6993     linkend="functions-geometry-func-table">, and <xref
6994     linkend="functions-geometry-conv-table">.
6995    </para>
6996
6997    <caution>
6998     <para>
6999      Note that the <quote>same as</> operator, <literal>~=</>, represents
7000      the usual notion of equality for the <type>point</type>,
7001      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
7002      Some of these types also have an <literal>=</> operator, but
7003      <literal>=</> compares
7004      for equal <emphasis>areas</> only.  The other scalar comparison operators
7005      (<literal>&lt;=</> and so on) likewise compare areas for these types.
7006     </para>
7007    </caution>
7008
7009    <table id="functions-geometry-op-table">
7010      <title>Geometric Operators</title>
7011      <tgroup cols="3">
7012       <thead>
7013        <row>
7014         <entry>Operator</entry>
7015         <entry>Description</entry>
7016         <entry>Example</entry>
7017        </row>
7018       </thead>
7019       <tbody>
7020        <row>
7021         <entry> <literal>+</literal> </entry>
7022         <entry>Translation</entry>
7023         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
7024        </row>
7025        <row>
7026         <entry> <literal>-</literal> </entry>
7027         <entry>Translation</entry>
7028         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
7029        </row>
7030        <row>
7031         <entry> <literal>*</literal> </entry>
7032         <entry>Scaling/rotation</entry>
7033         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
7034        </row>
7035        <row>
7036         <entry> <literal>/</literal> </entry>
7037         <entry>Scaling/rotation</entry>
7038         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
7039        </row>
7040        <row>
7041         <entry> <literal>#</literal> </entry>
7042         <entry>Point or box of intersection</entry>
7043         <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
7044        </row>
7045        <row>
7046         <entry> <literal>#</literal> </entry>
7047         <entry>Number of points in path or polygon</entry>
7048         <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
7049        </row>
7050        <row>
7051         <entry> <literal>@-@</literal> </entry>
7052         <entry>Length or circumference</entry>
7053         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
7054        </row>
7055        <row>
7056         <entry> <literal>@@</literal> </entry>
7057         <entry>Center</entry>
7058         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
7059        </row>
7060        <row>
7061         <entry> <literal>##</literal> </entry>
7062         <entry>Closest point to first operand on second operand</entry>
7063         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
7064        </row>
7065        <row>
7066         <entry> <literal>&lt;-&gt;</literal> </entry>
7067         <entry>Distance between</entry>
7068         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
7069        </row>
7070        <row>
7071         <entry> <literal>&amp;&amp;</literal> </entry>
7072         <entry>Overlaps?</entry>
7073         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
7074        </row>
7075        <row>
7076         <entry> <literal>&lt;&lt;</literal> </entry>
7077         <entry>Is strictly left of?</entry>
7078         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
7079        </row>
7080        <row>
7081         <entry> <literal>&gt;&gt;</literal> </entry>
7082         <entry>Is strictly right of?</entry>
7083         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
7084        </row>
7085        <row>
7086         <entry> <literal>&amp;&lt;</literal> </entry>
7087         <entry>Does not extend to the right of?</entry>
7088         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
7089        </row>
7090        <row>
7091         <entry> <literal>&amp;&gt;</literal> </entry>
7092         <entry>Does not extend to the left of?</entry>
7093         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
7094        </row>
7095        <row>
7096         <entry> <literal>&lt;&lt;|</literal> </entry>
7097         <entry>Is strictly below?</entry>
7098         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
7099        </row>
7100        <row>
7101         <entry> <literal>|&gt;&gt;</literal> </entry>
7102         <entry>Is strictly above?</entry>
7103         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
7104        </row>
7105        <row>
7106         <entry> <literal>&amp;&lt;|</literal> </entry>
7107         <entry>Does not extend above?</entry>
7108         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
7109        </row>
7110        <row>
7111         <entry> <literal>|&amp;&gt;</literal> </entry>
7112         <entry>Does not extend below?</entry>
7113         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
7114        </row>
7115        <row>
7116         <entry> <literal>&lt;^</literal> </entry>
7117         <entry>Is below (allows touching)?</entry>
7118         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
7119        </row>
7120        <row>
7121         <entry> <literal>&gt;^</literal> </entry>
7122         <entry>Is above (allows touching)?</entry>
7123         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
7124        </row>
7125        <row>
7126         <entry> <literal>?#</literal> </entry>
7127         <entry>Intersects?</entry>
7128         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7129        </row>
7130        <row>
7131         <entry> <literal>?-</literal> </entry>
7132         <entry>Is horizontal?</entry>
7133         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7134        </row>
7135        <row>
7136         <entry> <literal>?-</literal> </entry>
7137         <entry>Are horizontally aligned?</entry>
7138         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7139        </row>
7140        <row>
7141         <entry> <literal>?|</literal> </entry>
7142         <entry>Is vertical?</entry>
7143         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7144        </row>
7145        <row>
7146         <entry> <literal>?|</literal> </entry>
7147         <entry>Are vertically aligned?</entry>
7148         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7149        </row>
7150        <row>
7151         <entry> <literal>?-|</literal> </entry>
7152         <entry>Is perpendicular?</entry>
7153         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7154        </row>
7155        <row>
7156         <entry> <literal>?||</literal> </entry>
7157         <entry>Are parallel?</entry>
7158         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7159        </row>
7160        <row>
7161         <entry> <literal>@&gt;</literal> </entry>
7162         <entry>Contains?</entry>
7163         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7164        </row>
7165        <row>
7166         <entry> <literal>&lt;@</literal> </entry>
7167         <entry>Contained in or on?</entry>
7168         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7169        </row>
7170        <row>
7171         <entry> <literal>~=</literal> </entry>
7172         <entry>Same as?</entry>
7173         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7174        </row>
7175       </tbody>
7176      </tgroup>
7177    </table>
7178
7179    <note>
7180     <para>
7181      Before <productname>PostgreSQL</productname> 8.2, the containment
7182      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7183      called <literal>~</> and <literal>@</>.  These names are still
7184      available, but are deprecated and will eventually be removed.
7185     </para>
7186    </note>
7187
7188    <indexterm>
7189     <primary>area</primary>
7190    </indexterm>
7191    <indexterm>
7192     <primary>center</primary>
7193    </indexterm>
7194    <indexterm>
7195     <primary>diameter</primary>
7196    </indexterm>
7197    <indexterm>
7198     <primary>height</primary>
7199    </indexterm>
7200    <indexterm>
7201     <primary>isclosed</primary>
7202    </indexterm>
7203    <indexterm>
7204     <primary>isopen</primary>
7205    </indexterm>
7206    <indexterm>
7207     <primary>length</primary>
7208    </indexterm>
7209    <indexterm>
7210     <primary>npoints</primary>
7211    </indexterm>
7212    <indexterm>
7213     <primary>pclose</primary>
7214    </indexterm>
7215    <indexterm>
7216     <primary>popen</primary>
7217    </indexterm>
7218    <indexterm>
7219     <primary>radius</primary>
7220    </indexterm>
7221    <indexterm>
7222     <primary>width</primary>
7223    </indexterm>
7224
7225    <table id="functions-geometry-func-table">
7226      <title>Geometric Functions</title>
7227      <tgroup cols="4">
7228       <thead>
7229        <row>
7230         <entry>Function</entry>
7231         <entry>Return Type</entry>
7232         <entry>Description</entry>
7233         <entry>Example</entry>
7234        </row>
7235       </thead>
7236       <tbody>
7237        <row>
7238         <entry><literal><function>area</function>(<replaceable>object</>)</literal></entry>
7239         <entry><type>double precision</type></entry>
7240         <entry>area</entry>
7241         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7242        </row>
7243        <row>
7244         <entry><literal><function>center</function>(<replaceable>object</>)</literal></entry>
7245         <entry><type>point</type></entry>
7246         <entry>center</entry>
7247         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7248        </row>
7249        <row>
7250         <entry><literal><function>diameter</function>(<type>circle</>)</literal></entry>
7251         <entry><type>double precision</type></entry>
7252         <entry>diameter of circle</entry>
7253         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7254        </row>
7255        <row>
7256         <entry><literal><function>height</function>(<type>box</>)</literal></entry>
7257         <entry><type>double precision</type></entry>
7258         <entry>vertical size of box</entry>
7259         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7260        </row>
7261        <row>
7262         <entry><literal><function>isclosed</function>(<type>path</>)</literal></entry>
7263         <entry><type>boolean</type></entry>
7264         <entry>a closed path?</entry>
7265         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7266        </row>
7267        <row>
7268         <entry><literal><function>isopen</function>(<type>path</>)</literal></entry>
7269         <entry><type>boolean</type></entry>
7270         <entry>an open path?</entry>
7271         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7272        </row>
7273        <row>
7274         <entry><literal><function>length</function>(<replaceable>object</>)</literal></entry>
7275         <entry><type>double precision</type></entry>
7276         <entry>length</entry>
7277         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7278        </row>
7279        <row>
7280         <entry><literal><function>npoints</function>(<type>path</>)</literal></entry>
7281         <entry><type>int</type></entry>
7282         <entry>number of points</entry>
7283         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7284        </row>
7285        <row>
7286         <entry><literal><function>npoints</function>(<type>polygon</>)</literal></entry>
7287         <entry><type>int</type></entry>
7288         <entry>number of points</entry>
7289         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7290        </row>
7291        <row>
7292         <entry><literal><function>pclose</function>(<type>path</>)</literal></entry>
7293         <entry><type>path</type></entry>
7294         <entry>convert path to closed</entry>
7295         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7296        </row>
7297 <![IGNORE[
7298 <!-- Not defined by this name. Implements the intersection operator '#' -->
7299        <row>
7300         <entry><literal><function>point</function>(<type>lseg</>, <type>lseg</>)</literal></entry>
7301         <entry><type>point</type></entry>
7302         <entry>intersection</entry>
7303         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7304        </row>
7305 ]]>
7306        <row>
7307         <entry><literal><function>popen</function>(<type>path</>)</literal></entry>
7308         <entry><type>path</type></entry>
7309         <entry>convert path to open</entry>
7310         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7311        </row>
7312        <row>
7313         <entry><literal><function>radius</function>(<type>circle</type>)</literal></entry>
7314         <entry><type>double precision</type></entry>
7315         <entry>radius of circle</entry>
7316         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7317        </row>
7318        <row>
7319         <entry><literal><function>width</function>(<type>box</>)</literal></entry>
7320         <entry><type>double precision</type></entry>
7321         <entry>horizontal size of box</entry>
7322         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7323        </row>
7324       </tbody>
7325      </tgroup>
7326    </table>
7327
7328    <table id="functions-geometry-conv-table">
7329      <title>Geometric Type Conversion Functions</title>
7330      <tgroup cols="4">
7331       <thead>
7332        <row>
7333         <entry>Function</entry>
7334         <entry>Return Type</entry>
7335         <entry>Description</entry>
7336         <entry>Example</entry>
7337        </row>
7338       </thead>
7339       <tbody>
7340        <row>
7341         <entry><literal><function>box</function>(<type>circle</type>)</literal></entry>
7342         <entry><type>box</type></entry>
7343         <entry>circle to box</entry>
7344         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7345        </row>
7346        <row>
7347         <entry><literal><function>box</function>(<type>point</type>, <type>point</type>)</literal></entry>
7348         <entry><type>box</type></entry>
7349         <entry>points to box</entry>
7350         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7351        </row>
7352        <row>
7353         <entry><literal><function>box</function>(<type>polygon</type>)</literal></entry>
7354         <entry><type>box</type></entry>
7355         <entry>polygon to box</entry>
7356         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7357        </row>
7358        <row>
7359         <entry><literal><function>circle</function>(<type>box</type>)</literal></entry>
7360         <entry><type>circle</type></entry>
7361         <entry>box to circle</entry>
7362         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7363        </row>
7364        <row>
7365         <entry><literal><function>circle</function>(<type>point</type>, <type>double precision</type>)</literal></entry>
7366         <entry><type>circle</type></entry>
7367         <entry>center and radius to circle</entry>
7368         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7369        </row>
7370        <row>
7371         <entry><literal><function>circle</function>(<type>polygon</type>)</literal></entry>
7372         <entry><type>circle</type></entry>
7373         <entry>polygon to circle</entry>
7374         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7375        </row>
7376        <row>
7377         <entry><literal><function>lseg</function>(<type>box</type>)</literal></entry>
7378         <entry><type>lseg</type></entry>
7379         <entry>box diagonal to line segment</entry>
7380         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7381        </row>
7382        <row>
7383         <entry><literal><function>lseg</function>(<type>point</type>, <type>point</type>)</literal></entry>
7384         <entry><type>lseg</type></entry>
7385         <entry>points to line segment</entry>
7386         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7387        </row>
7388        <row>
7389         <entry><literal><function>path</function>(<type>polygon</type>)</literal></entry>
7390         <entry><type>point</type></entry>
7391         <entry>polygon to path</entry>
7392         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7393        </row>
7394        <row>
7395         <entry><literal><function>point</function>(<type>double
7396          precision</type>, <type>double precision</type>)</literal></entry>
7397         <entry><type>point</type></entry>
7398         <entry>construct point</entry>
7399         <entry><literal>point(23.4, -44.5)</literal></entry>
7400        </row>
7401        <row>
7402         <entry><literal><function>point</function>(<type>box</type>)</literal></entry>
7403         <entry><type>point</type></entry>
7404         <entry>center of box</entry>
7405         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7406        </row>
7407        <row>
7408         <entry><literal><function>point</function>(<type>circle</type>)</literal></entry>
7409         <entry><type>point</type></entry>
7410         <entry>center of circle</entry>
7411         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7412        </row>
7413        <row>
7414         <entry><literal><function>point</function>(<type>lseg</type>)</literal></entry>
7415         <entry><type>point</type></entry>
7416         <entry>center of line segment</entry>
7417         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7418        </row>
7419        <row>
7420         <entry><literal><function>point</function>(<type>polygon</type>)</literal></entry>
7421         <entry><type>point</type></entry>
7422         <entry>center of polygon</entry>
7423         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7424        </row>
7425        <row>
7426         <entry><literal><function>polygon</function>(<type>box</type>)</literal></entry>
7427         <entry><type>polygon</type></entry>
7428         <entry>box to 4-point polygon</entry>
7429         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7430        </row>
7431        <row>
7432         <entry><literal><function>polygon</function>(<type>circle</type>)</literal></entry>
7433         <entry><type>polygon</type></entry>
7434         <entry>circle to 12-point polygon</entry>
7435         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7436        </row>
7437        <row>
7438         <entry><literal><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</literal></entry>
7439         <entry><type>polygon</type></entry>
7440         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
7441         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7442        </row>
7443        <row>
7444         <entry><literal><function>polygon</function>(<type>path</type>)</literal></entry>
7445         <entry><type>polygon</type></entry>
7446         <entry>path to polygon</entry>
7447         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7448        </row>
7449       </tbody>
7450      </tgroup>
7451    </table>
7452
7453     <para>
7454      It is possible to access the two component numbers of a <type>point</>
7455      as though the point were an array with indexes 0 and 1.  For example, if
7456      <literal>t.p</> is a <type>point</> column then
7457      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7458      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7459      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7460      as an array of two <type>point</> values.
7461     </para>
7462
7463     <para>
7464      The <function>area</function> function works for the types
7465      <type>box</type>, <type>circle</type>, and <type>path</type>.
7466      The <function>area</function> function only works on the
7467      <type>path</type> data type if the points in the
7468      <type>path</type> are non-intersecting.  For example, the
7469      <type>path</type>
7470      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7471      will not work;  however, the following visually identical
7472      <type>path</type>
7473      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7474      will work.  If the concept of an intersecting versus
7475      non-intersecting <type>path</type> is confusing, draw both of the
7476      above <type>path</type>s side by side on a piece of graph paper.
7477     </para>
7478
7479   </sect1>
7480
7481
7482  <sect1 id="functions-net">
7483   <title>Network Address Functions and Operators</title>
7484
7485   <para>
7486    <xref linkend="cidr-inet-operators-table"> shows the operators
7487    available for the <type>cidr</type> and <type>inet</type> types.
7488    The operators <literal>&lt;&lt;</literal>,
7489    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
7490    <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
7491    consider only the network parts of the two addresses (ignoring any
7492    host part) and determine whether one network is identical to
7493    or a subnet of the other.
7494   </para>
7495
7496     <table id="cidr-inet-operators-table">
7497      <title><type>cidr</type> and <type>inet</type> Operators</title>
7498      <tgroup cols="3">
7499       <thead>
7500        <row>
7501         <entry>Operator</entry>
7502         <entry>Description</entry>
7503         <entry>Example</entry>
7504        </row>
7505       </thead>
7506       <tbody>
7507        <row>
7508         <entry> <literal>&lt;</literal> </entry>
7509         <entry>is less than</entry>
7510         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
7511        </row>
7512        <row>
7513         <entry> <literal>&lt;=</literal> </entry>
7514         <entry>is less than or equal</entry>
7515         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
7516        </row>
7517        <row>
7518         <entry> <literal>=</literal> </entry>
7519         <entry>equals</entry>
7520         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
7521        </row>
7522        <row>
7523         <entry> <literal>&gt;=</literal> </entry>
7524         <entry>is greater or equal</entry>
7525         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
7526        </row>
7527        <row>
7528         <entry> <literal>&gt;</literal> </entry>
7529         <entry>is greater than</entry>
7530         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
7531        </row>
7532        <row>
7533         <entry> <literal>&lt;&gt;</literal> </entry>
7534         <entry>is not equal</entry>
7535         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
7536        </row>
7537        <row>
7538         <entry> <literal>&lt;&lt;</literal> </entry>
7539         <entry>is contained within</entry>
7540         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
7541        </row>
7542        <row>
7543         <entry> <literal>&lt;&lt;=</literal> </entry>
7544         <entry>is contained within or equals</entry>
7545         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
7546        </row>
7547        <row>
7548         <entry> <literal>&gt;&gt;</literal> </entry>
7549         <entry>contains</entry>
7550         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
7551        </row>
7552        <row>
7553         <entry> <literal>&gt;&gt;=</literal> </entry>
7554         <entry>contains or equals</entry>
7555         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
7556        </row>
7557        <row>
7558         <entry> <literal>~</literal> </entry>
7559         <entry>bitwise NOT</entry>
7560         <entry><literal>~ inet '192.168.1.6'</literal></entry>
7561        </row>
7562        <row>
7563         <entry> <literal>&amp;</literal> </entry>
7564         <entry>bitwise AND</entry>
7565         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
7566        </row>
7567        <row>
7568         <entry> <literal>|</literal> </entry>
7569         <entry>bitwise OR</entry>
7570         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
7571        </row>
7572        <row>
7573         <entry> <literal>+</literal> </entry>
7574         <entry>addition</entry>
7575         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
7576        </row>
7577        <row>
7578         <entry> <literal>-</literal> </entry>
7579         <entry>subtraction</entry>
7580         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
7581        </row>
7582        <row>
7583         <entry> <literal>-</literal> </entry>
7584         <entry>subtraction</entry>
7585         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
7586        </row>
7587       </tbody>
7588      </tgroup>
7589     </table>
7590
7591   <para>
7592    <xref linkend="cidr-inet-functions-table"> shows the functions
7593    available for use with the <type>cidr</type> and <type>inet</type>
7594    types.  The <function>abbrev</function>, <function>host</function>,
7595    and <function>text</function>
7596    functions are primarily intended to offer alternative display
7597    formats.
7598   </para>
7599
7600     <table id="cidr-inet-functions-table">
7601      <title><type>cidr</type> and <type>inet</type> Functions</title>
7602      <tgroup cols="5">
7603       <thead>
7604        <row>
7605         <entry>Function</entry>
7606         <entry>Return Type</entry>
7607         <entry>Description</entry>
7608         <entry>Example</entry>
7609         <entry>Result</entry>
7610        </row>
7611       </thead>
7612       <tbody>
7613        <row>
7614         <entry><literal><function>abbrev</function>(<type>inet</type>)</literal></entry>
7615         <entry><type>text</type></entry>
7616         <entry>abbreviated display format as text</entry>
7617         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
7618         <entry><literal>10.1.0.0/16</literal></entry>
7619        </row>
7620        <row>
7621         <entry><literal><function>abbrev</function>(<type>cidr</type>)</literal></entry>
7622         <entry><type>text</type></entry>
7623         <entry>abbreviated display format as text</entry>
7624         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
7625         <entry><literal>10.1/16</literal></entry>
7626        </row>
7627        <row>
7628         <entry><literal><function>broadcast</function>(<type>inet</type>)</literal></entry>
7629         <entry><type>inet</type></entry>
7630         <entry>broadcast address for network</entry>
7631         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
7632         <entry><literal>192.168.1.255/24</literal></entry>
7633        </row>
7634        <row>
7635         <entry><literal><function>family</function>(<type>inet</type>)</literal></entry>
7636         <entry><type>int</type></entry>
7637         <entry>extract family of address; <literal>4</literal> for IPv4,
7638          <literal>6</literal> for IPv6</entry>
7639         <entry><literal>family('::1')</literal></entry>
7640         <entry><literal>6</literal></entry>
7641        </row>
7642        <row>
7643         <entry><literal><function>host</function>(<type>inet</type>)</literal></entry>
7644         <entry><type>text</type></entry>
7645         <entry>extract IP address as text</entry>
7646         <entry><literal>host('192.168.1.5/24')</literal></entry>
7647         <entry><literal>192.168.1.5</literal></entry>
7648        </row>
7649        <row>
7650         <entry><literal><function>hostmask</function>(<type>inet</type>)</literal></entry>
7651         <entry><type>inet</type></entry>
7652         <entry>construct host mask for network</entry>
7653         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
7654         <entry><literal>0.0.0.3</literal></entry>
7655        </row>
7656        <row>
7657         <entry><literal><function>masklen</function>(<type>inet</type>)</literal></entry>
7658         <entry><type>int</type></entry>
7659         <entry>extract netmask length</entry>
7660         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
7661         <entry><literal>24</literal></entry>
7662        </row>
7663        <row>
7664         <entry><literal><function>netmask</function>(<type>inet</type>)</literal></entry>
7665         <entry><type>inet</type></entry>
7666         <entry>construct netmask for network</entry>
7667         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
7668         <entry><literal>255.255.255.0</literal></entry>
7669        </row>
7670        <row>
7671         <entry><literal><function>network</function>(<type>inet</type>)</literal></entry>
7672         <entry><type>cidr</type></entry>
7673         <entry>extract network part of address</entry>
7674         <entry><literal>network('192.168.1.5/24')</literal></entry>
7675         <entry><literal>192.168.1.0/24</literal></entry>
7676        </row>
7677        <row>
7678         <entry><literal><function>set_masklen</function>(<type>inet</type>, <type>int</type>)</literal></entry>
7679         <entry><type>inet</type></entry>
7680         <entry>set netmask length for <type>inet</type> value</entry>
7681         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
7682         <entry><literal>192.168.1.5/16</literal></entry>
7683        </row>
7684        <row>
7685         <entry><literal><function>set_masklen</function>(<type>cidr</type>, <type>int</type>)</literal></entry>
7686         <entry><type>cidr</type></entry>
7687         <entry>set netmask length for <type>cidr</type> value</entry>
7688         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
7689         <entry><literal>192.168.0.0/16</literal></entry>
7690        </row>
7691        <row>
7692         <entry><literal><function>text</function>(<type>inet</type>)</literal></entry>
7693         <entry><type>text</type></entry>
7694         <entry>extract IP address and netmask length as text</entry>
7695         <entry><literal>text(inet '192.168.1.5')</literal></entry>
7696         <entry><literal>192.168.1.5/32</literal></entry>
7697        </row>
7698       </tbody>
7699      </tgroup>
7700     </table>
7701
7702   <para>
7703    Any <type>cidr</> value can be cast to <type>inet</> implicitly
7704    or explicitly; therefore, the functions shown above as operating on
7705    <type>inet</> also work on <type>cidr</> values.  (Where there are
7706    separate functions for <type>inet</> and <type>cidr</>, it is because
7707    the behavior should be different for the two cases.)
7708    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
7709    When this is done, any bits to the right of the netmask are silently zeroed
7710    to create a valid <type>cidr</> value.
7711    In addition,
7712    you can cast a text value to <type>inet</> or <type>cidr</>
7713    using normal casting syntax: for example,
7714    <literal>inet(<replaceable>expression</>)</literal> or
7715    <literal><replaceable>colname</>::cidr</literal>.
7716   </para>
7717
7718   <para>
7719    <xref linkend="macaddr-functions-table"> shows the functions
7720    available for use with the <type>macaddr</type> type.  The function
7721    <literal><function>trunc</function>(<type>macaddr</type>)</literal> returns a MAC
7722    address with the last 3 bytes set to zero.  This can be used to
7723    associate the remaining prefix with a manufacturer.
7724   </para>
7725
7726     <table id="macaddr-functions-table">
7727      <title><type>macaddr</type> Functions</title>
7728      <tgroup cols="5">
7729       <thead>
7730        <row>
7731         <entry>Function</entry>
7732         <entry>Return Type</entry>
7733         <entry>Description</entry>
7734         <entry>Example</entry>
7735         <entry>Result</entry>
7736        </row>
7737       </thead>
7738       <tbody>
7739        <row>
7740         <entry><literal><function>trunc</function>(<type>macaddr</type>)</literal></entry>
7741         <entry><type>macaddr</type></entry>
7742         <entry>set last 3 bytes to zero</entry>
7743         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
7744         <entry><literal>12:34:56:00:00:00</literal></entry>
7745        </row>
7746       </tbody>
7747      </tgroup>
7748     </table>
7749
7750    <para>
7751     The <type>macaddr</type> type also supports the standard relational
7752     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
7753     lexicographical ordering.
7754    </para>
7755
7756   </sect1>
7757
7758
7759  <sect1 id="functions-textsearch">
7760   <title>Text Search Functions and Operators</title>
7761
7762    <indexterm zone="datatype-textsearch">
7763     <primary>full text search</primary>
7764     <secondary>functions and operators</secondary>
7765    </indexterm>
7766
7767    <indexterm zone="datatype-textsearch">
7768     <primary>text search</primary>
7769     <secondary>functions and operators</secondary>
7770    </indexterm>
7771
7772   <para>
7773    <xref linkend="textsearch-operators-table">,
7774    <xref linkend="textsearch-functions-table"> and
7775    <xref linkend="textsearch-functions-debug-table">
7776    summarize the functions and operators that are provided
7777    for full text searching.  See <xref linkend="textsearch"> for a detailed
7778    explanation of <productname>PostgreSQL</productname>'s text search
7779    facility.
7780   </para>
7781
7782     <table id="textsearch-operators-table">
7783      <title>Text Search Operators</title>
7784      <tgroup cols="4">
7785       <thead>
7786        <row>
7787         <entry>Operator</entry>
7788         <entry>Description</entry>
7789         <entry>Example</entry>
7790         <entry>Result</entry>
7791        </row>
7792       </thead>
7793       <tbody>
7794        <row>
7795         <entry> <literal>@@</literal> </entry>
7796         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
7797         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
7798         <entry><literal>t</literal></entry>
7799        </row>
7800        <row>
7801         <entry> <literal>@@@</literal> </entry>
7802         <entry>deprecated synonym for <literal>@@</></entry>
7803         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
7804         <entry><literal>t</literal></entry>
7805        </row>
7806        <row>
7807         <entry> <literal>||</literal> </entry>
7808         <entry>concatenate <type>tsvector</>s</entry>
7809         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
7810         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
7811        </row>
7812        <row>
7813         <entry> <literal>&amp;&amp;</literal> </entry>
7814         <entry>AND <type>tsquery</>s together</entry>
7815         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
7816         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
7817        </row>
7818        <row>
7819         <entry> <literal>||</literal> </entry>
7820         <entry>OR <type>tsquery</>s together</entry>
7821         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
7822         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
7823        </row>
7824        <row>
7825         <entry> <literal>!!</literal> </entry>
7826         <entry>negate a <type>tsquery</></entry>
7827         <entry><literal>!! 'cat'::tsquery</literal></entry>
7828         <entry><literal>!'cat'</literal></entry>
7829        </row>
7830        <row>
7831         <entry> <literal>@&gt;</literal> </entry>
7832         <entry><type>tsquery</> contains another ?</entry>
7833         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
7834         <entry><literal>f</literal></entry>
7835        </row>
7836        <row>
7837         <entry> <literal>&lt;@</literal> </entry>
7838         <entry><type>tsquery</> is contained in ?</entry>
7839         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
7840         <entry><literal>t</literal></entry>
7841        </row>
7842       </tbody>
7843      </tgroup>
7844     </table>
7845
7846     <note>
7847      <para>
7848       The <type>tsquery</> containment operators consider only the lexemes
7849       listed in the two queries, ignoring the combining operators.
7850      </para>
7851     </note>
7852
7853     <para>
7854      In addition to the operators shown in the table, the ordinary B-tree
7855      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
7856      for types <type>tsvector</> and <type>tsquery</>.  These are not very
7857      useful for text searching but allow, for example, unique indexes to be
7858      built on columns of these types.
7859     </para>
7860
7861     <table id="textsearch-functions-table">
7862      <title>Text Search Functions</title>
7863      <tgroup cols="5">
7864       <thead>
7865        <row>
7866         <entry>Function</entry>
7867         <entry>Return Type</entry>
7868         <entry>Description</entry>
7869         <entry>Example</entry>
7870         <entry>Result</entry>
7871        </row>
7872       </thead>
7873       <tbody>
7874        <row>
7875         <entry><literal><function>to_tsvector</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</literal></entry>
7876         <entry><type>tsvector</type></entry>
7877         <entry>reduce document text to <type>tsvector</></entry>
7878         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
7879         <entry><literal>'fat':2 'rat':3</literal></entry>
7880        </row>
7881        <row>
7882         <entry><literal><function>length</function>(<type>tsvector</>)</literal></entry>
7883         <entry><type>integer</type></entry>
7884         <entry>number of lexemes in <type>tsvector</></entry>
7885         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7886         <entry><literal>3</literal></entry>
7887        </row>
7888        <row>
7889         <entry><literal><function>setweight</function>(<type>tsvector</>, <type>"char"</>)</literal></entry>
7890         <entry><type>tsvector</type></entry>
7891         <entry>assign weight to each element of <type>tsvector</></entry>
7892         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
7893         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
7894        </row>
7895        <row>
7896         <entry><literal><function>strip</function>(<type>tsvector</>)</literal></entry>
7897         <entry><type>tsvector</type></entry>
7898         <entry>remove positions and weights from <type>tsvector</></entry>
7899         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7900         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
7901        </row>
7902        <row>
7903         <entry><literal><function>to_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7904         <entry><type>tsquery</type></entry>
7905         <entry>normalize words and convert to <type>tsquery</></entry>
7906         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
7907         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7908        </row>
7909        <row>
7910         <entry><literal><function>plainto_tsquery</function>(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</literal></entry>
7911         <entry><type>tsquery</type></entry>
7912         <entry>produce <type>tsquery</> ignoring punctuation</entry>
7913         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
7914         <entry><literal>'fat' &amp; 'rat'</literal></entry>
7915        </row>
7916        <row>
7917         <entry><literal><function>numnode</function>(<type>tsquery</>)</literal></entry>
7918         <entry><type>integer</type></entry>
7919         <entry>number of lexemes plus operators in <type>tsquery</></entry>
7920         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
7921         <entry><literal>5</literal></entry>
7922        </row>
7923        <row>
7924         <entry><literal><function>querytree</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</literal></entry>
7925         <entry><type>text</type></entry>
7926         <entry>get indexable part of a <type>tsquery</></entry>
7927         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
7928         <entry><literal>'foo'</literal></entry>
7929        </row>
7930        <row>
7931         <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>
7932         <entry><type>float4</type></entry>
7933         <entry>rank document for query</entry>
7934         <entry><literal>ts_rank(textsearch, query)</literal></entry>
7935         <entry><literal>0.818</literal></entry>
7936        </row>
7937        <row>
7938         <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>
7939         <entry><type>float4</type></entry>
7940         <entry>rank document for query using cover density</entry>
7941         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
7942         <entry><literal>2.01317</literal></entry>
7943        </row>
7944        <row>
7945         <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>
7946         <entry><type>text</type></entry>
7947         <entry>display a query match</entry>
7948         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
7949         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
7950        </row>
7951        <row>
7952         <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>
7953         <entry><type>tsquery</type></entry>
7954         <entry>replace target with substitute within query</entry>
7955         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
7956         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7957        </row>
7958        <row>
7959         <entry><literal><function>ts_rewrite</function>(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</literal></entry>
7960         <entry><type>tsquery</type></entry>
7961         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
7962         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
7963         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
7964        </row>
7965        <row>
7966         <entry><literal><function>get_current_ts_config</function>()</literal></entry>
7967         <entry><type>regconfig</type></entry>
7968         <entry>get default text search configuration</entry>
7969         <entry><literal>get_current_ts_config()</literal></entry>
7970         <entry><literal>english</literal></entry>
7971        </row>
7972        <row>
7973         <entry><literal><function>tsvector_update_trigger</function>()</literal></entry>
7974         <entry><type>trigger</type></entry>
7975         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7976         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
7977         <entry><literal></literal></entry>
7978        </row>
7979        <row>
7980         <entry><literal><function>tsvector_update_trigger_column</function>()</literal></entry>
7981         <entry><type>trigger</type></entry>
7982         <entry>trigger function for automatic <type>tsvector</> column update</entry>
7983         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
7984         <entry><literal></literal></entry>
7985         <entry><literal></literal></entry>
7986        </row>
7987       </tbody>
7988      </tgroup>
7989     </table>
7990
7991   <note>
7992    <para>
7993     All the text search functions that accept an optional <type>regconfig</>
7994     argument will use the configuration specified by
7995     <xref linkend="guc-default-text-search-config">
7996     when that argument is omitted.
7997    </para>
7998   </note>
7999
8000   <para>
8001    The functions in
8002    <xref linkend="textsearch-functions-debug-table">
8003    are listed separately because they are not usually used in everyday text
8004    searching operations.  They are helpful for development and debugging
8005    of new text search configurations.
8006   </para>
8007
8008     <table id="textsearch-functions-debug-table">
8009      <title>Text Search Debugging Functions</title>
8010      <tgroup cols="5">
8011       <thead>
8012        <row>
8013         <entry>Function</entry>
8014         <entry>Return Type</entry>
8015         <entry>Description</entry>
8016         <entry>Example</entry>
8017         <entry>Result</entry>
8018        </row>
8019       </thead>
8020       <tbody>
8021        <row>
8022         <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>
8023         <entry><type>setof record</type></entry>
8024         <entry>test a configuration</entry>
8025         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
8026         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
8027        </row>
8028        <row>
8029         <entry><literal><function>ts_lexize</function>(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</literal></entry>
8030         <entry><type>text[]</type></entry>
8031         <entry>test a dictionary</entry>
8032         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
8033         <entry><literal>{star}</literal></entry>
8034        </row>
8035        <row>
8036         <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>
8037         <entry><type>setof record</type></entry>
8038         <entry>test a parser</entry>
8039         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
8040         <entry><literal>(1,foo) ...</literal></entry>
8041        </row>
8042        <row>
8043         <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>
8044         <entry><type>setof record</type></entry>
8045         <entry>test a parser</entry>
8046         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
8047         <entry><literal>(1,foo) ...</literal></entry>
8048        </row>
8049        <row>
8050         <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>
8051         <entry><type>setof record</type></entry>
8052         <entry>get token types defined by parser</entry>
8053         <entry><literal>ts_token_type('default')</literal></entry>
8054         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8055        </row>
8056        <row>
8057         <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>
8058         <entry><type>setof record</type></entry>
8059         <entry>get token types defined by parser</entry>
8060         <entry><literal>ts_token_type(3722)</literal></entry>
8061         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
8062        </row>
8063        <row>
8064         <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>
8065         <entry><type>setof record</type></entry>
8066         <entry>get statistics of a <type>tsvector</> column</entry>
8067         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
8068         <entry><literal>(foo,10,15) ...</literal></entry>
8069        </row>
8070       </tbody>
8071      </tgroup>
8072     </table>
8073
8074  </sect1>
8075
8076
8077  <sect1 id="functions-xml">
8078   <title>XML Functions</title>
8079
8080   <para>
8081    The functions and function-like expressions described in this
8082    section operate on values of type <type>xml</type>.  Check <xref
8083    linkend="datatype-xml"> for information about the <type>xml</type>
8084    type.  The function-like expressions <function>xmlparse</function>
8085    and <function>xmlserialize</function> for converting to and from
8086    type <type>xml</type> are not repeated here.  Use of many of these
8087    functions requires the installation to have been built
8088    with <command>configure --with-libxml</>.
8089   </para>
8090
8091   <sect2>
8092    <title>Producing XML Content</title>
8093
8094    <para>
8095     A set of functions and function-like expressions are available for
8096     producing XML content from SQL data.  As such, they are
8097     particularly suitable for formatting query results into XML
8098     documents for processing in client applications.
8099    </para>
8100
8101    <sect3>
8102     <title><literal>xmlcomment</literal></title>
8103
8104     <indexterm>
8105      <primary>xmlcomment</primary>
8106     </indexterm>
8107
8108 <synopsis>
8109 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8110 </synopsis>
8111
8112     <para>
8113      The function <function>xmlcomment</function> creates an XML value
8114      containing an XML comment with the specified text as content.
8115      The text cannot contain <quote><literal>--</literal></quote> or end with a
8116      <quote><literal>-</literal></quote> so that the resulting construct is a valid
8117      XML comment.  If the argument is null, the result is null.
8118     </para>
8119
8120     <para>
8121      Example:
8122 <screen><![CDATA[
8123 SELECT xmlcomment('hello');
8124
8125   xmlcomment
8126 --------------
8127  <!--hello-->
8128 ]]></screen>
8129     </para>
8130    </sect3>
8131
8132    <sect3>
8133     <title><literal>xmlconcat</literal></title>
8134
8135     <indexterm>
8136      <primary>xmlconcat</primary>
8137     </indexterm>
8138
8139  <synopsis>
8140  <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8141  </synopsis>
8142  
8143     <para>
8144      The function <function>xmlconcat</function> concatenates a list
8145      of individual XML values to create a single value containing an
8146      XML content fragment.  Null values are omitted; the result is
8147      only null if there are no nonnull arguments.
8148     </para>
8149
8150     <para>
8151      Example:
8152 <screen><![CDATA[
8153 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8154
8155       xmlconcat
8156 ----------------------
8157  <abc/><bar>foo</bar>
8158 ]]></screen>
8159     </para>
8160
8161     <para>
8162      XML declarations, if present, are combined as follows.  If all
8163      argument values have the same XML version declaration, that
8164      version is used in the result, else no version is used.  If all
8165      argument values have the standalone declaration value
8166      <quote>yes</quote>, then that value is used in the result.  If
8167      all argument values have a standalone declaration value and at
8168      least one is <quote>no</quote>, then that is used in the result.
8169      Else the result will have no standalone declaration.  If the
8170      result is determined to require a standalone declaration but no
8171      version declaration, a version declaration with version 1.0 will
8172      be used because XML requires an XML declaration to contain a
8173      version declaration.  Encoding declarations are ignored and
8174      removed in all cases.
8175     </para>
8176
8177     <para>
8178      Example:
8179 <screen><![CDATA[
8180 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
8181
8182              xmlconcat
8183 -----------------------------------
8184  <?xml version="1.1"?><foo/><bar/>
8185 ]]></screen>
8186     </para>
8187    </sect3>
8188  
8189    <sect3>
8190     <title><literal>xmlelement</literal></title>
8191  
8192    <indexterm>
8193     <primary>xmlelement</primary>
8194    </indexterm>
8195  
8196 <synopsis>
8197  <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>)
8198  </synopsis>
8199  
8200     <para>
8201      The <function>xmlelement</function> expression produces an XML
8202      element with the given name, attributes, and content.
8203     </para>
8204
8205     <para>
8206      Examples:
8207 <screen><![CDATA[
8208 SELECT xmlelement(name foo);
8209
8210  xmlelement
8211 ------------
8212  <foo/>
8213
8214 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8215
8216     xmlelement
8217 ------------------
8218  <foo bar="xyz"/>
8219
8220 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8221
8222              xmlelement
8223 -------------------------------------
8224  <foo bar="2007-01-26">content</foo>
8225 ]]></screen>
8226     </para>
8227
8228     <para>
8229      Element and attribute names that are not valid XML names are
8230      escaped by replacing the offending characters by the sequence
8231      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8232      <replaceable>HHHH</replaceable> is the character's Unicode
8233      codepoint in hexadecimal notation.  For example:
8234 <screen><![CDATA[
8235 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
8236
8237             xmlelement
8238 ----------------------------------
8239  <foo_x0024_bar a_x0026_b="xyz"/>
8240 ]]></screen>
8241     </para>
8242
8243     <para>
8244      An explicit attribute name need not be specified if the attribute
8245      value is a column reference, in which case the column's name will
8246      be used as the attribute name by default.  In other cases, the
8247      attribute must be given an explicit name.  So this example is
8248      valid:
8249 <screen>
8250 CREATE TABLE test (a xml, b xml);
8251 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8252 </screen>
8253      But these are not:
8254 <screen>
8255 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8256 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8257 </screen>
8258     </para>
8259
8260     <para>
8261      Element content, if specified, will be formatted according to
8262      its data type.  If the content is itself of type <type>xml</type>,
8263      complex XML documents can be constructed.  For example:
8264 <screen><![CDATA[
8265 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8266                             xmlelement(name abc),
8267                             xmlcomment('test'),
8268                             xmlelement(name xyz));
8269
8270                   xmlelement
8271 ----------------------------------------------
8272  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
8273 ]]></screen>
8274
8275      Content of other types will be formatted into valid XML character
8276      data.  This means in particular that the characters &lt;, &gt;,
8277      and &amp; will be converted to entities.  Binary data (data type
8278      <type>bytea</type>) will be represented in base64 or hex
8279      encoding, depending on the setting of the configuration parameter
8280      <xref linkend="guc-xmlbinary">.  The particular behavior for
8281      individual data types is expected to evolve in order to align the
8282      SQL and PostgreSQL data types with the XML Schema specification,
8283      at which point a more precise description will appear.
8284     </para>
8285    </sect3>
8286  
8287    <sect3>
8288     <title><literal>xmlforest</literal></title>
8289  
8290    <indexterm>
8291     <primary>xmlforest</primary>
8292    </indexterm>
8293  
8294  <synopsis>
8295  <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8296  </synopsis>
8297  
8298     <para>
8299      The <function>xmlforest</function> expression produces an XML
8300      forest (sequence) of elements using the given names and content.
8301     </para>
8302
8303     <para>
8304      Examples:
8305 <screen><![CDATA[
8306 SELECT xmlforest('abc' AS foo, 123 AS bar);
8307
8308           xmlforest
8309 ------------------------------
8310  <foo>abc</foo><bar>123</bar>
8311
8312
8313 SELECT xmlforest(table_name, column_name)
8314 FROM information_schema.columns
8315 WHERE table_schema = 'pg_catalog';
8316
8317                                          xmlforest
8318 -------------------------------------------------------------------------------------------
8319  <table_name>pg_authid</table_name><column_name>rolname</column_name>
8320  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8321  ...
8322 ]]></screen>
8323
8324      As seen in the second example, the element name can be omitted if
8325      the content value is a column reference, in which case the column
8326      name is used by default.  Otherwise, a name must be specified.
8327     </para>
8328
8329     <para>
8330      Element names that are not valid XML names are escaped as shown
8331      for <function>xmlelement</function> above.  Similarly, content
8332      data is escaped to make valid XML content, unless it is already
8333      of type <type>xml</type>.
8334     </para>
8335
8336     <para>
8337      Note that XML forests are not valid XML documents if they consist
8338      of more than one element, so it might be useful to wrap
8339      <function>xmlforest</function> expressions in
8340      <function>xmlelement</function>.
8341     </para>
8342    </sect3>
8343  
8344    <sect3>
8345     <title><literal>xmlpi</literal></title>
8346  
8347    <indexterm>
8348     <primary>xmlpi</primary>
8349    </indexterm>
8350  
8351  <synopsis>
8352  <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
8353  </synopsis>
8354  
8355     <para>
8356      The <function>xmlpi</function> expression creates an XML
8357      processing instruction.  The content, if present, must not
8358      contain the character sequence <literal>?&gt;</literal>.
8359     </para>
8360
8361     <para>
8362      Example:
8363 <screen><![CDATA[
8364 SELECT xmlpi(name php, 'echo "hello world";');
8365
8366             xmlpi
8367 -----------------------------
8368  <?php echo "hello world";?>
8369 ]]></screen>
8370     </para>
8371    </sect3>
8372  
8373    <sect3>
8374     <title><literal>xmlroot</literal></title>
8375  
8376    <indexterm>
8377     <primary>xmlroot</primary>
8378    </indexterm>
8379  
8380  <synopsis>
8381  <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
8382  </synopsis>
8383  
8384     <para>
8385      The <function>xmlroot</function> expression alters the properties
8386      of the root node of an XML value.  If a version is specified,
8387      it replaces the value in the root node's version declaration; if a
8388      standalone setting is specified, it replaces the value in the
8389      root node's standalone declaration.
8390     </para>
8391
8392     <para>
8393 <screen><![CDATA[
8394 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'), 
8395                version '1.0', standalone yes);
8396
8397                 xmlroot
8398 ----------------------------------------
8399  <?xml version="1.0" standalone="yes"?>
8400  <content>abc</content>
8401 ]]></screen>
8402     </para>
8403    </sect3>
8404
8405    <sect3 id="functions-xml-xmlagg">
8406     <title><literal>xmlagg</literal></title>
8407
8408     <indexterm>
8409      <primary>xmlagg</primary>
8410     </indexterm>
8411
8412 <synopsis>
8413 <function>xmlagg</function>(<replaceable>xml</replaceable>)
8414 </synopsis>
8415
8416     <para>
8417      The function <function>xmlagg</function> is, unlike the other
8418      functions described here, an aggregate function.  It concatenates the
8419      input values to the aggregate function call,
8420      like <function>xmlconcat</function> does.
8421      See <xref linkend="functions-aggregate"> for additional information
8422      about aggregate functions.
8423     </para>
8424
8425     <para>
8426      Example:
8427 <screen><![CDATA[
8428 CREATE TABLE test (y int, x xml);
8429 INSERT INTO test VALUES (1, '<foo>abc</foo>');
8430 INSERT INTO test VALUES (2, '<bar/>');
8431 SELECT xmlagg(x) FROM test;
8432         xmlagg
8433 ----------------------
8434  <foo>abc</foo><bar/>
8435 ]]></screen>
8436     </para>
8437
8438     <para>
8439      To determine the order of the concatenation, something like the
8440      following approach can be used:
8441
8442 <screen><![CDATA[
8443 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
8444         xmlagg
8445 ----------------------
8446  <bar/><foo>abc</foo>
8447 ]]></screen>
8448
8449      Again, see <xref linkend="functions-aggregate"> for additional
8450      information.
8451     </para>
8452    </sect3>
8453
8454    <sect3>
8455     <title>XML Predicates</title>
8456
8457     <indexterm>
8458      <primary>IS DOCUMENT</primary>
8459     </indexterm>
8460
8461 <synopsis>
8462 <replaceable>xml</replaceable> IS DOCUMENT
8463 </synopsis>
8464
8465     <para>
8466      The expression <literal>IS DOCUMENT</literal> returns true if the
8467      argument XML value is a proper XML document, false if it is not
8468      (that is, it is a content fragment), or null if the argument is
8469      null.  See <xref linkend="datatype-xml"> about the difference
8470      between documents and content fragments.
8471     </para>
8472    </sect3>
8473   </sect2>
8474
8475   <sect2 id="functions-xml-processing">
8476    <title>Processing XML</title>
8477
8478    <indexterm>
8479     <primary>XPath</primary>
8480    </indexterm>
8481
8482    <para>
8483     To process values of data type <type>xml</type>, PostgreSQL offers
8484     the function <function>xpath</function>, which evaluates XPath 1.0
8485     expressions.
8486    </para>
8487
8488 <synopsis>
8489 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable><optional>, <replaceable>nsarray</replaceable></optional>)
8490 </synopsis>
8491
8492    <para>
8493     The function <function>xpath</function> evaluates the XPath
8494     expression <replaceable>xpath</replaceable> against the XML value
8495     <replaceable>xml</replaceable>.  It returns an array of XML values
8496     corresponding to the node set produced by the XPath expression.
8497    </para>
8498
8499   <para>
8500     The second argument must be a well formed XML document. In particular,
8501     it must have a single root node element.
8502   </para>
8503
8504    <para>
8505     The third argument of the function is an array of namespace
8506     mappings.  This array should be a two-dimensional array with the
8507     length of the second axis being equal to 2 (i.e., it should be an
8508     array of arrays, each of which consists of exactly 2 elements).
8509     The first element of each array entry is the namespace name, the
8510     second the namespace URI.
8511    </para>
8512
8513    <para>
8514     Example:
8515 <screen><![CDATA[
8516 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', 
8517              ARRAY[ARRAY['my', 'http://example.com']]);
8518
8519  xpath  
8520 --------
8521  {test}
8522 (1 row)
8523 ]]></screen>
8524    </para>
8525   </sect2>
8526
8527   <sect2 id="functions-xml-mapping">
8528    <title>Mapping Tables to XML</title>
8529
8530    <indexterm zone="functions-xml-mapping"> 
8531     <primary>XML export</primary>
8532    </indexterm>
8533
8534    <para>
8535     The following functions map the contents of relational tables to
8536     XML values.  They can be thought of as XML export functionality:
8537 <synopsis>
8538 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8539 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
8540 cursor_to_xml(cursor refcursor, count int, nulls boolean, 
8541               tableforest boolean, targetns text)
8542 </synopsis>
8543     The return type of each function is <type>xml</type>.
8544    </para>
8545
8546    <para>
8547     <function>table_to_xml</function> maps the content of the named
8548     table, passed as parameter <parameter>tbl</parameter>.  The
8549     <type>regclass</type> type accepts strings identifying tables using the
8550     usual notation, including optional schema qualifications and
8551     double quotes.  <function>query_to_xml</function> executes the
8552     query whose text is passed as parameter
8553     <parameter>query</parameter> and maps the result set.
8554     <function>cursor_to_xml</function> fetches the indicated number of
8555     rows from the cursor specified by the parameter
8556     <parameter>cursor</parameter>.  This variant is recommended if
8557     large tables have to be mapped, because the result value is built
8558     up in memory by each function.
8559    </para>
8560
8561    <para>
8562     If <parameter>tableforest</parameter> is false, then the resulting
8563     XML document looks like this:
8564 <screen><![CDATA[
8565 <tablename>
8566   <row>
8567     <columnname1>data</columnname1>
8568     <columnname2>data</columnname2>
8569   </row>
8570
8571   <row>
8572     ...
8573   </row>
8574
8575   ...
8576 </tablename>
8577 ]]></screen>
8578
8579     If <parameter>tableforest</parameter> is true, the result is an
8580     XML content fragment that looks like this:
8581 <screen><![CDATA[
8582 <tablename>
8583   <columnname1>data</columnname1>
8584   <columnname2>data</columnname2>
8585 </tablename>
8586
8587 <tablename>
8588   ...
8589 </tablename>
8590
8591 ...
8592 ]]></screen>
8593
8594     If no table name is available, that is, when mapping a query or a
8595     cursor, the string <literal>table</literal> is used in the first
8596     format, <literal>row</literal> in the second format.
8597    </para>
8598
8599    <para>
8600     The choice between these formats is up to the user.  The first
8601     format is a proper XML document, which will be important in many
8602     applications.  The second format tends to be more useful in the
8603     <function>cursor_to_xml</function> function if the result values are to be
8604     reassembled into one document later on.  The functions for
8605     producing XML content discussed above, in particular
8606     <function>xmlelement</function>, can be used to alter the results
8607     to taste.
8608    </para>
8609
8610    <para>
8611     The data values are mapped in the same way as described for the
8612     function <function>xmlelement</function> above.
8613    </para>
8614
8615    <para>
8616     The parameter <parameter>nulls</parameter> determines whether null
8617     values should be included in the output.  If true, null values in
8618     columns are represented as:
8619 <screen><![CDATA[
8620 <columnname xsi:nil="true"/>
8621 ]]></screen>
8622     where <literal>xsi</literal> is the XML namespace prefix for XML
8623     Schema Instance.  An appropriate namespace declaration will be
8624     added to the result value.  If false, columns containing null
8625     values are simply omitted from the output.
8626    </para>
8627
8628    <para>
8629     The parameter <parameter>targetns</parameter> specifies the
8630     desired XML namespace of the result.  If no particular namespace
8631     is wanted, an empty string should be passed.
8632    </para>
8633
8634    <para>
8635     The following functions return XML Schema documents describing the
8636     mappings performed by the corresponding functions above:
8637 <synopsis>
8638 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8639 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8640 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
8641 </synopsis>
8642     It is essential that the same parameters are passed in order to
8643     obtain matching XML data mappings and XML Schema documents.
8644    </para>
8645
8646    <para>
8647     The following functions produce XML data mappings and the
8648     corresponding XML Schema in one document (or forest), linked
8649     together.  They can be useful where self-contained and
8650     self-describing results are wanted:
8651 <synopsis>
8652 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8653 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8654 </synopsis>
8655    </para>
8656
8657    <para>
8658     In addition, the following functions are available to produce
8659     analogous mappings of entire schemas or the entire current
8660     database:
8661 <synopsis>
8662 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
8663 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8664 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8665
8666 database_to_xml(nulls boolean, tableforest boolean, targetns text)
8667 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
8668 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
8669 </synopsis>
8670
8671     Note that these potentially produce a lot of data, which needs to
8672     be built up in memory.  When requesting content mappings of large
8673     schemas or databases, it might be worthwhile to consider mapping the
8674     tables separately instead, possibly even through a cursor.
8675    </para>
8676
8677    <para>
8678     The result of a schema content mapping looks like this:
8679
8680 <screen><![CDATA[
8681 <schemaname>
8682
8683 table1-mapping
8684
8685 table2-mapping
8686
8687 ...
8688
8689 </schemaname>]]></screen>
8690
8691     where the format of a table mapping depends on the
8692     <parameter>tableforest</parameter> parameter as explained above.
8693    </para>
8694
8695    <para>
8696     The result of a database content mapping looks like this:
8697
8698 <screen><![CDATA[
8699 <dbname>
8700
8701 <schema1name>
8702   ...
8703 </schema1name>
8704
8705 <schema2name>
8706   ...
8707 </schema2name>
8708
8709 ...
8710
8711 </dbname>]]></screen>
8712
8713     where the schema mapping is as above.
8714    </para>
8715
8716    <para>
8717     As an example of using the output produced by these functions,
8718     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
8719     converts the output of
8720     <function>table_to_xml_and_xmlschema</function> to an HTML
8721     document containing a tabular rendition of the table data.  In a
8722     similar manner, the results from these functions can be
8723     converted into other XML-based formats.
8724    </para>
8725
8726    <figure id="xslt-xml-html">
8727     <title>XSLT stylesheet for converting SQL/XML output to HTML</title>
8728 <programlisting><![CDATA[
8729 <?xml version="1.0"?>
8730 <xsl:stylesheet version="1.0"
8731     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
8732     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
8733     xmlns="http://www.w3.org/1999/xhtml"
8734 >
8735
8736   <xsl:output method="xml"
8737       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
8738       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
8739       indent="yes"/>
8740
8741   <xsl:template match="/*">
8742     <xsl:variable name="schema" select="//xsd:schema"/>
8743     <xsl:variable name="tabletypename"
8744                   select="$schema/xsd:element[@name=name(current())]/@type"/>
8745     <xsl:variable name="rowtypename"
8746                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
8747
8748     <html>
8749       <head>
8750         <title><xsl:value-of select="name(current())"/></title>
8751       </head>
8752       <body>
8753         <table>
8754           <tr>
8755             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
8756               <th><xsl:value-of select="."/></th>
8757             </xsl:for-each>
8758           </tr>
8759
8760           <xsl:for-each select="row">
8761             <tr>
8762               <xsl:for-each select="*">
8763                 <td><xsl:value-of select="."/></td>
8764               </xsl:for-each>
8765             </tr>
8766           </xsl:for-each>
8767         </table>
8768       </body>
8769     </html>
8770   </xsl:template>
8771
8772 </xsl:stylesheet>
8773 ]]></programlisting>
8774    </figure>
8775   </sect2>
8776  </sect1>
8777
8778
8779  <sect1 id="functions-sequence">
8780   <title>Sequence Manipulation Functions</title>
8781
8782   <indexterm>
8783    <primary>sequence</primary>
8784   </indexterm>
8785   <indexterm>
8786    <primary>nextval</primary>
8787   </indexterm>
8788   <indexterm>
8789    <primary>currval</primary>
8790   </indexterm>
8791   <indexterm>
8792    <primary>lastval</primary>
8793   </indexterm>
8794   <indexterm>
8795    <primary>setval</primary>
8796   </indexterm>
8797
8798   <para>
8799    This section describes <productname>PostgreSQL</productname>'s
8800    functions for operating on <firstterm>sequence objects</firstterm>.
8801    Sequence objects (also called sequence generators or just
8802    sequences) are special single-row tables created with <xref
8803    linkend="sql-createsequence" endterm="sql-createsequence-title">.
8804    A sequence object is usually used to generate unique identifiers
8805    for rows of a table.  The sequence functions, listed in <xref
8806    linkend="functions-sequence-table">, provide simple, multiuser-safe
8807    methods for obtaining successive sequence values from sequence
8808    objects.
8809   </para>
8810
8811    <table id="functions-sequence-table">
8812     <title>Sequence Functions</title>
8813     <tgroup cols="3">
8814      <thead>
8815       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
8816      </thead>
8817
8818      <tbody>
8819       <row>
8820         <entry><literal><function>currval</function>(<type>regclass</type>)</literal></entry>
8821         <entry><type>bigint</type></entry>
8822         <entry>Return value most recently obtained with
8823         <function>nextval</function> for specified sequence</entry>
8824       </row>
8825       <row>
8826         <entry><literal><function>lastval</function>()</literal></entry>
8827         <entry><type>bigint</type></entry>
8828         <entry>Return value most recently obtained with
8829         <function>nextval</function> for any sequence</entry>
8830       </row>
8831       <row>
8832         <entry><literal><function>nextval</function>(<type>regclass</type>)</literal></entry>
8833         <entry><type>bigint</type></entry>
8834         <entry>Advance sequence and return new value</entry>
8835       </row>
8836       <row>
8837         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>)</literal></entry>
8838         <entry><type>bigint</type></entry>
8839         <entry>Set sequence's current value</entry>
8840       </row>
8841       <row>
8842         <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</literal></entry>
8843         <entry><type>bigint</type></entry>
8844         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
8845       </row>
8846      </tbody>
8847     </tgroup>
8848    </table>
8849
8850   <para>
8851    The sequence to be operated on by a sequence function is specified by
8852    a <type>regclass</> argument, which is simply the OID of the sequence in the
8853    <structname>pg_class</> system catalog.  You do not have to look up the
8854    OID by hand, however, since the <type>regclass</> data type's input
8855    converter will do the work for you.  Just write the sequence name enclosed
8856    in single quotes so that it looks like a literal constant.  For
8857    compatibility with the handling of ordinary
8858    <acronym>SQL</acronym> names, the string will be converted to lowercase
8859    unless it contains double quotes around the sequence name.  Thus:
8860 <programlisting>
8861 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
8862 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
8863 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
8864 </programlisting>
8865    The sequence name can be schema-qualified if necessary:
8866 <programlisting>
8867 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
8868 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
8869 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
8870 </programlisting>
8871    See <xref linkend="datatype-oid"> for more information about
8872    <type>regclass</>.
8873   </para>
8874
8875   <note>
8876    <para>
8877     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
8878     sequence functions were of type <type>text</>, not <type>regclass</>, and
8879     the above-described conversion from a text string to an OID value would
8880     happen at run time during each call.  For backwards compatibility, this
8881     facility still exists, but internally it is now handled as an implicit
8882     coercion from <type>text</> to <type>regclass</> before the function is
8883     invoked.
8884    </para>
8885
8886    <para>
8887     When you write the argument of a sequence function as an unadorned
8888     literal string, it becomes a constant of type <type>regclass</>.
8889     Since this is really just an OID, it will track the originally
8890     identified sequence despite later renaming, schema reassignment,
8891     etc.  This <quote>early binding</> behavior is usually desirable for
8892     sequence references in column defaults and views.  But sometimes you might
8893     want <quote>late binding</> where the sequence reference is resolved
8894     at run time.  To get late-binding behavior, force the constant to be
8895     stored as a <type>text</> constant instead of <type>regclass</>:
8896 <programlisting>
8897 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
8898 </programlisting>
8899     Note that late binding was the only behavior supported in
8900     <productname>PostgreSQL</productname> releases before 8.1, so you
8901     might need to do this to preserve the semantics of old applications.
8902    </para>
8903
8904    <para>
8905     Of course, the argument of a sequence function can be an expression
8906     as well as a constant.  If it is a text expression then the implicit
8907     coercion will result in a run-time lookup.
8908    </para>
8909   </note>
8910
8911   <para>
8912    The available sequence functions are:
8913
8914     <variablelist>
8915      <varlistentry>
8916       <term><function>nextval</function></term>
8917       <listitem>
8918        <para>
8919         Advance the sequence object to its next value and return that
8920         value.  This is done atomically: even if multiple sessions
8921         execute <function>nextval</function> concurrently, each will safely receive
8922         a distinct sequence value.
8923        </para>
8924       </listitem>
8925      </varlistentry>
8926
8927      <varlistentry>
8928       <term><function>currval</function></term>
8929       <listitem>
8930        <para>
8931         Return the value most recently obtained by <function>nextval</function>
8932         for this sequence in the current session.  (An error is
8933         reported if <function>nextval</function> has never been called for this
8934         sequence in this session.)  Because this is returning
8935         a session-local value, it gives a predictable answer whether or not
8936         other sessions have executed <function>nextval</function> since the
8937         current session did.
8938        </para>
8939       </listitem>
8940      </varlistentry>
8941
8942      <varlistentry>
8943       <term><function>lastval</function></term>
8944       <listitem>
8945        <para>
8946         Return the value most recently returned by
8947         <function>nextval</> in the current session. This function is
8948         identical to <function>currval</function>, except that instead
8949         of taking the sequence name as an argument it fetches the
8950         value of the last sequence used by <function>nextval</function>
8951         in the current session. It is an error to call
8952         <function>lastval</function> if <function>nextval</function>
8953         has not yet been called in the current session.
8954        </para>
8955       </listitem>
8956      </varlistentry>
8957
8958      <varlistentry>
8959       <term><function>setval</function></term>
8960       <listitem>
8961        <para>
8962         Reset the sequence object's counter value.  The two-parameter
8963         form sets the sequence's <literal>last_value</literal> field to the
8964         specified value and sets its <literal>is_called</literal> field to
8965         <literal>true</literal>, meaning that the next
8966         <function>nextval</function> will advance the sequence before
8967         returning a value.  The value reported by <function>currval</> is
8968         also set to the specified value.  In the three-parameter form,
8969         <literal>is_called</literal> can be set to either <literal>true</literal>
8970         or <literal>false</literal>.  <literal>true</> has the same effect as
8971         the two-parameter form. If it is set to <literal>false</literal>, the
8972         next <function>nextval</function> will return exactly the specified
8973         value, and sequence advancement commences with the following
8974         <function>nextval</function>.  Furthermore, the value reported by
8975         <function>currval</> is not changed in this case (this is a change
8976         from pre-8.3 behavior).  For example,
8977
8978 <screen>
8979 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
8980 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
8981 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
8982 </screen>
8983
8984         The result returned by <function>setval</function> is just the value of its
8985         second argument.
8986        </para>
8987       </listitem>
8988      </varlistentry>
8989     </variablelist>
8990   </para>
8991
8992   <para>
8993    If a sequence object has been created with default parameters,
8994    successive <function>nextval</function> calls will return successive values
8995    beginning with 1.  Other behaviors can be obtained by using
8996    special parameters in the <xref linkend="sql-createsequence" endterm="sql-createsequence-title"> command;
8997    see its command reference page for more information.
8998   </para>
8999
9000   <important>
9001    <para>
9002     To avoid blocking concurrent transactions that obtain numbers from the
9003     same sequence, a <function>nextval</function> operation is never rolled back;
9004     that is, once a value has been fetched it is considered used, even if the
9005     transaction that did the <function>nextval</function> later aborts.  This means
9006     that aborted transactions might leave unused <quote>holes</quote> in the
9007     sequence of assigned values.  <function>setval</function> operations are never
9008     rolled back, either.
9009    </para>
9010   </important>
9011
9012  </sect1>
9013
9014
9015  <sect1 id="functions-conditional">
9016   <title>Conditional Expressions</title>
9017
9018   <indexterm>
9019    <primary>CASE</primary>
9020   </indexterm>
9021
9022   <indexterm>
9023    <primary>conditional expression</primary>
9024   </indexterm>
9025
9026   <para>
9027    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
9028    available in <productname>PostgreSQL</productname>.
9029   </para>
9030
9031   <tip>
9032    <para>
9033     If your needs go beyond the capabilities of these conditional
9034     expressions, you might want to consider writing a stored procedure
9035     in a more expressive programming language.
9036    </para>
9037   </tip>
9038
9039   <sect2>
9040    <title><literal>CASE</></title>
9041
9042   <para>
9043    The <acronym>SQL</acronym> <token>CASE</token> expression is a
9044    generic conditional expression, similar to if/else statements in
9045    other programming languages:
9046
9047 <synopsis>
9048 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
9049      <optional>WHEN ...</optional>
9050      <optional>ELSE <replaceable>result</replaceable></optional>
9051 END
9052 </synopsis>
9053
9054    <token>CASE</token> clauses can be used wherever
9055    an expression is valid.  Each <replaceable>condition</replaceable> is an
9056    expression that returns a <type>boolean</type> result.  If the condition's
9057    result is true, the value of the <token>CASE</token> expression is the
9058    <replaceable>result</replaceable> that follows the condition, and the
9059    remainder of the <token>CASE</token> expression is not processed.  If the
9060    condition's result is not true, any subsequent <token>WHEN</token> clauses
9061    are examined in the same manner.  If no <token>WHEN</token>
9062    <replaceable>condition</replaceable> yields true, the value of the
9063    <token>CASE</> expression is the <replaceable>result</replaceable> of the
9064    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
9065    omitted and no condition is true, the result is null.
9066   </para>
9067
9068    <para>
9069     An example:
9070 <screen>
9071 SELECT * FROM test;
9072
9073  a
9074 ---
9075  1
9076  2
9077  3
9078
9079
9080 SELECT a,
9081        CASE WHEN a=1 THEN 'one'
9082             WHEN a=2 THEN 'two'
9083             ELSE 'other'
9084        END
9085     FROM test;
9086
9087  a | case
9088 ---+-------
9089  1 | one
9090  2 | two
9091  3 | other
9092 </screen>
9093    </para>
9094
9095   <para>
9096    The data types of all the <replaceable>result</replaceable>
9097    expressions must be convertible to a single output type.
9098    See <xref linkend="typeconv-union-case"> for more details.
9099   </para>
9100
9101   <para>
9102    There is a <quote>simple</> form of <token>CASE</token> expression
9103    that is a variant of the general form above:
9104
9105 <synopsis>
9106 CASE <replaceable>expression</replaceable>
9107     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
9108     <optional>WHEN ...</optional>
9109     <optional>ELSE <replaceable>result</replaceable></optional>
9110 END
9111 </synopsis>
9112
9113    The first
9114    <replaceable>expression</replaceable> is computed, then compared to
9115    each of the <replaceable>value</replaceable> expressions in the
9116    <token>WHEN</token> clauses until one is found that is equal to it.  If
9117    no match is found, the <replaceable>result</replaceable> of the
9118    <token>ELSE</token> clause (or a null value) is returned.  This is similar
9119    to the <function>switch</function> statement in C.
9120   </para>
9121
9122    <para>
9123     The example above can be written using the simple
9124     <token>CASE</token> syntax:
9125 <screen>
9126 SELECT a,
9127        CASE a WHEN 1 THEN 'one'
9128               WHEN 2 THEN 'two'
9129               ELSE 'other'
9130        END
9131     FROM test;
9132
9133  a | case
9134 ---+-------
9135  1 | one
9136  2 | two
9137  3 | other
9138 </screen>
9139    </para>
9140
9141    <para>
9142     A <token>CASE</token> expression does not evaluate any subexpressions
9143     that are not needed to determine the result.  For example, this is a
9144     possible way of avoiding a division-by-zero failure:
9145 <programlisting>
9146 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
9147 </programlisting>
9148    </para>
9149   </sect2>
9150
9151   <sect2>
9152    <title><literal>COALESCE</></title>
9153
9154   <indexterm>
9155    <primary>COALESCE</primary>
9156   </indexterm>
9157
9158   <indexterm>
9159    <primary>NVL</primary>
9160   </indexterm>
9161
9162   <indexterm>
9163    <primary>IFNULL</primary>
9164   </indexterm>
9165
9166 <synopsis>
9167 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9168 </synopsis>
9169
9170   <para>
9171    The <function>COALESCE</function> function returns the first of its
9172    arguments that is not null.  Null is returned only if all arguments
9173    are null.  It is often used to substitute a default value for 
9174    null values when data is retrieved for display, for example:
9175 <programlisting>
9176 SELECT COALESCE(description, short_description, '(none)') ...
9177 </programlisting>
9178   </para>
9179
9180    <para>
9181     Like a <token>CASE</token> expression, <function>COALESCE</function> only
9182     evaluates the arguments that are needed to determine the result;
9183     that is, arguments to the right of the first non-null argument are
9184     not evaluated.  This SQL-standard function provides capabilities similar
9185     to <function>NVL</> and <function>IFNULL</>, which are used in some other
9186     database systems.
9187    </para>
9188   </sect2>
9189
9190   <sect2>
9191    <title><literal>NULLIF</></title>
9192
9193   <indexterm>
9194    <primary>NULLIF</primary>
9195   </indexterm>
9196
9197 <synopsis>
9198 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
9199 </synopsis>
9200
9201   <para>
9202    The <function>NULLIF</function> function returns a null value if
9203    <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
9204    otherwise it returns <replaceable>value1</replaceable>.
9205    This can be used to perform the inverse operation of the
9206    <function>COALESCE</function> example given above:
9207 <programlisting>
9208 SELECT NULLIF(value, '(none)') ...
9209 </programlisting>
9210   </para>
9211   <para>
9212    In this example, if <literal>value</literal> is <literal>(none)</>,
9213    null is returned, otherwise the value of <literal>value</literal>
9214    is returned.
9215   </para>
9216
9217   </sect2>
9218
9219   <sect2>
9220    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
9221
9222   <indexterm>
9223    <primary>GREATEST</primary>
9224   </indexterm>
9225   <indexterm>
9226    <primary>LEAST</primary>
9227   </indexterm>
9228
9229 <synopsis>
9230 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9231 </synopsis>
9232 <synopsis>
9233 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9234 </synopsis>
9235
9236    <para>
9237     The <function>GREATEST</> and <function>LEAST</> functions select the
9238     largest or smallest value from a list of any number of expressions.
9239     The expressions must all be convertible to a common data type, which
9240     will be the type of the result
9241     (see <xref linkend="typeconv-union-case"> for details).  NULL values
9242     in the list are ignored.  The result will be NULL only if all the
9243     expressions evaluate to NULL.
9244    </para>
9245
9246    <para>
9247     Note that <function>GREATEST</> and <function>LEAST</> are not in
9248     the SQL standard, but are a common extension.  Some other databases
9249     make them return NULL if any argument is NULL, rather than only when
9250     all are NULL.
9251    </para>
9252   </sect2>
9253  </sect1>
9254
9255  <sect1 id="functions-array">
9256   <title>Array Functions and Operators</title>
9257
9258   <para>
9259    <xref linkend="array-operators-table"> shows the operators
9260    available for array types.
9261   </para>
9262
9263     <table id="array-operators-table">
9264      <title>Array Operators</title>
9265      <tgroup cols="4">
9266       <thead>
9267        <row>
9268         <entry>Operator</entry>
9269         <entry>Description</entry>
9270         <entry>Example</entry>
9271         <entry>Result</entry>
9272        </row>
9273       </thead>
9274       <tbody>
9275        <row>
9276         <entry> <literal>=</literal> </entry>
9277         <entry>equal</entry>
9278         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
9279         <entry><literal>t</literal></entry>
9280        </row>
9281
9282        <row>
9283         <entry> <literal>&lt;&gt;</literal> </entry>
9284         <entry>not equal</entry>
9285         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
9286         <entry><literal>t</literal></entry>
9287        </row>
9288
9289        <row>
9290         <entry> <literal>&lt;</literal> </entry>
9291         <entry>less than</entry>
9292         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
9293         <entry><literal>t</literal></entry>
9294        </row>
9295
9296        <row>
9297         <entry> <literal>&gt;</literal> </entry>
9298         <entry>greater than</entry>
9299         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
9300         <entry><literal>t</literal></entry>
9301        </row>
9302
9303        <row>
9304         <entry> <literal>&lt;=</literal> </entry>
9305         <entry>less than or equal</entry>
9306         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
9307         <entry><literal>t</literal></entry>
9308        </row>
9309
9310        <row>
9311         <entry> <literal>&gt;=</literal> </entry>
9312         <entry>greater than or equal</entry>
9313         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
9314         <entry><literal>t</literal></entry>
9315        </row>
9316
9317        <row>
9318         <entry> <literal>@&gt;</literal> </entry>
9319         <entry>contains</entry>
9320         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
9321         <entry><literal>t</literal></entry>
9322        </row>
9323
9324        <row>
9325         <entry> <literal>&lt;@</literal> </entry>
9326         <entry>is contained by</entry>
9327         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
9328         <entry><literal>t</literal></entry>
9329        </row>
9330
9331        <row>
9332         <entry> <literal>&amp;&amp;</literal> </entry>
9333         <entry>overlap (have elements in common)</entry>
9334         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
9335         <entry><literal>t</literal></entry>
9336        </row>
9337
9338        <row>
9339         <entry> <literal>||</literal> </entry>
9340         <entry>array-to-array concatenation</entry>
9341         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
9342         <entry><literal>{1,2,3,4,5,6}</literal></entry>
9343        </row>
9344
9345        <row>
9346         <entry> <literal>||</literal> </entry>
9347         <entry>array-to-array concatenation</entry>
9348         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
9349         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
9350        </row>
9351
9352        <row>
9353         <entry> <literal>||</literal> </entry>
9354         <entry>element-to-array concatenation</entry>
9355         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
9356         <entry><literal>{3,4,5,6}</literal></entry>
9357        </row>
9358
9359        <row>
9360         <entry> <literal>||</literal> </entry>
9361         <entry>array-to-element concatenation</entry>
9362         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
9363         <entry><literal>{4,5,6,7}</literal></entry>
9364        </row>
9365       </tbody>
9366      </tgroup>
9367     </table>
9368
9369   <para>
9370    Array comparisons compare the array contents element-by-element,
9371    using the default B-Tree comparison function for the element data type.
9372    In multidimensional arrays the elements are visited in row-major order
9373    (last subscript varies most rapidly).
9374    If the contents of two arrays are equal but the dimensionality is
9375    different, the first difference in the dimensionality information
9376    determines the sort order.  (This is a change from versions of
9377    <productname>PostgreSQL</> prior to 8.2: older versions would claim
9378    that two arrays with the same contents were equal, even if the
9379    number of dimensions or subscript ranges were different.)
9380   </para>
9381
9382   <para>
9383    See <xref linkend="arrays"> for more details about array operator
9384    behavior.
9385   </para>
9386
9387   <para>
9388    <xref linkend="array-functions-table"> shows the functions
9389    available for use with array types. See <xref linkend="arrays">
9390    for more information  and examples of the use of these functions.
9391   </para>
9392
9393   <indexterm>
9394     <primary>array_append</primary>
9395   </indexterm>
9396   <indexterm>
9397     <primary>array_cat</primary>
9398   </indexterm>
9399   <indexterm>
9400     <primary>array_ndims</primary>
9401   </indexterm>
9402   <indexterm>
9403     <primary>array_dims</primary>
9404   </indexterm>
9405   <indexterm>
9406     <primary>array_fill</primary>
9407   </indexterm>
9408   <indexterm>
9409     <primary>array_length</primary>
9410   </indexterm>
9411   <indexterm>
9412     <primary>array_lower</primary>
9413   </indexterm>
9414   <indexterm>
9415     <primary>array_prepend</primary>
9416   </indexterm>
9417   <indexterm>
9418     <primary>array_to_string</primary>
9419   </indexterm>
9420  <indexterm>
9421     <primary>array_upper</primary>
9422   </indexterm>
9423   <indexterm>
9424     <primary>string_to_array</primary>
9425   </indexterm>
9426   <indexterm>
9427     <primary>unnest</primary>
9428   </indexterm>
9429
9430     <table id="array-functions-table">
9431      <title>Array Functions</title>
9432      <tgroup cols="5">
9433       <thead>
9434        <row>
9435         <entry>Function</entry>
9436         <entry>Return Type</entry>
9437         <entry>Description</entry>
9438         <entry>Example</entry>
9439         <entry>Result</entry>
9440        </row>
9441       </thead>
9442       <tbody>
9443        <row>
9444         <entry>
9445          <literal>
9446           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
9447          </literal>
9448         </entry>
9449         <entry><type>anyarray</type></entry>
9450         <entry>append an element to the end of an array</entry>
9451         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
9452         <entry><literal>{1,2,3}</literal></entry>
9453        </row>
9454        <row>
9455         <entry>
9456          <literal>
9457           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
9458          </literal>
9459         </entry>
9460         <entry><type>anyarray</type></entry>
9461         <entry>concatenate two arrays</entry>
9462         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
9463         <entry><literal>{1,2,3,4,5}</literal></entry>
9464        </row>
9465        <row>
9466         <entry>
9467          <literal>
9468           <function>array_ndims</function>(<type>anyarray</type>)
9469          </literal>
9470         </entry>
9471         <entry><type>int</type></entry>
9472         <entry>returns the number of dimensions of the array</entry>
9473         <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9474         <entry><literal>2</literal></entry>
9475        </row>
9476        <row>
9477         <entry>
9478          <literal>
9479           <function>array_dims</function>(<type>anyarray</type>)
9480          </literal>
9481         </entry>
9482         <entry><type>text</type></entry>
9483         <entry>returns a text representation of array's dimensions</entry>
9484         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9485         <entry><literal>[1:2][1:3]</literal></entry>
9486        </row>
9487        <row>
9488         <entry>
9489          <literal>
9490           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
9491           <optional>, <type>int[]</type></optional>)
9492          </literal>
9493         </entry>
9494         <entry><type>anyarray</type></entry>
9495         <entry>returns an array initialized with supplied value and
9496          dimensions, optionally with lower bounds other than 1</entry>
9497         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
9498         <entry><literal>[2:4]={7,7,7}</literal></entry>
9499        </row>
9500        <row>
9501         <entry>
9502          <literal>
9503           <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
9504          </literal>
9505         </entry>
9506         <entry><type>int</type></entry>
9507         <entry>returns the length of the requested array dimension</entry>
9508         <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
9509         <entry><literal>3</literal></entry>
9510        </row>
9511        <row>
9512         <entry>
9513          <literal>
9514           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
9515          </literal>
9516         </entry>
9517         <entry><type>int</type></entry>
9518         <entry>returns lower bound of the requested array dimension</entry>
9519         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
9520         <entry><literal>0</literal></entry>
9521        </row>
9522        <row>
9523         <entry>
9524          <literal>
9525           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
9526          </literal>
9527         </entry>
9528         <entry><type>anyarray</type></entry>
9529         <entry>append an element to the beginning of an array</entry>
9530         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
9531         <entry><literal>{1,2,3}</literal></entry>
9532        </row>
9533        <row>
9534         <entry>
9535          <literal>
9536           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type>)
9537          </literal>
9538         </entry>
9539         <entry><type>text</type></entry>
9540         <entry>concatenates array elements using supplied delimiter</entry>
9541         <entry><literal>array_to_string(ARRAY[1, 2, 3], '~^~')</literal></entry>
9542         <entry><literal>1~^~2~^~3</literal></entry>
9543        </row>
9544        <row>
9545         <entry>
9546          <literal>
9547           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
9548          </literal>
9549         </entry>
9550         <entry><type>int</type></entry>
9551         <entry>returns upper bound of the requested array dimension</entry>
9552         <entry><literal>array_upper(ARRAY[1,2,3,4], 1)</literal></entry>
9553         <entry><literal>4</literal></entry>
9554        </row>
9555        <row>
9556         <entry>
9557          <literal>
9558           <function>string_to_array</function>(<type>text</type>, <type>text</type>)
9559          </literal>
9560         </entry>
9561         <entry><type>text[]</type></entry>
9562         <entry>splits string into array elements using supplied delimiter</entry>
9563         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~')</literal></entry>
9564         <entry><literal>{xx,yy,zz}</literal></entry>
9565        </row>
9566        <row>
9567         <entry>
9568          <literal>
9569           <function>unnest</function>(<type>anyarray</type>)
9570          </literal>
9571         </entry>
9572         <entry><type>setof anyelement</type></entry>
9573         <entry>expand an array to a set of rows</entry>
9574         <entry><literal>unnest(ARRAY[1,2])</literal></entry>
9575         <entry><literal>1</literal><para><literal>2</literal></para> (2 rows)</entry>
9576        </row>
9577       </tbody>
9578      </tgroup>
9579     </table>
9580
9581    <para>
9582     See also <xref linkend="functions-aggregate"> about the aggregate
9583     function <function>array_agg</function> for use with arrays.
9584    </para>
9585   </sect1>
9586
9587  <sect1 id="functions-aggregate">
9588   <title>Aggregate Functions</title>
9589
9590   <indexterm zone="functions-aggregate">
9591    <primary>aggregate function</primary>
9592    <secondary>built-in</secondary>
9593   </indexterm>
9594
9595   <para>
9596    <firstterm>Aggregate functions</firstterm> compute a single result
9597    from a set of input values.  The built-in aggregate functions
9598    are listed in
9599    <xref linkend="functions-aggregate-table"> and
9600    <xref linkend="functions-aggregate-statistics-table">.
9601    The special syntax considerations for aggregate
9602    functions are explained in <xref linkend="syntax-aggregates">.
9603    Consult <xref linkend="tutorial-agg"> for additional introductory
9604    information.
9605   </para>
9606
9607   <table id="functions-aggregate-table">
9608    <title>General-Purpose Aggregate Functions</title>
9609
9610    <tgroup cols="4">
9611     <thead>
9612      <row>
9613       <entry>Function</entry>
9614       <entry>Argument Type</entry>
9615       <entry>Return Type</entry>
9616       <entry>Description</entry>
9617      </row>
9618     </thead>
9619
9620     <tbody>
9621      <row>
9622       <entry>
9623        <indexterm>
9624         <primary>array_agg</primary>
9625        </indexterm>
9626        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
9627       </entry>
9628       <entry>
9629        any
9630       </entry>
9631       <entry>
9632        array of the argument type
9633       </entry>
9634       <entry>input values concatenated into an array</entry>
9635      </row>
9636
9637      <row>
9638       <entry>
9639        <indexterm>
9640         <primary>average</primary>
9641        </indexterm>
9642        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
9643       </entry>
9644       <entry>
9645        <type>smallint</type>, <type>int</type>,
9646        <type>bigint</type>, <type>real</type>, <type>double
9647        precision</type>, <type>numeric</type>, or <type>interval</type>
9648       </entry>
9649       <entry>
9650        <type>numeric</type> for any integer-type argument,
9651        <type>double precision</type> for a floating-point argument,
9652        otherwise the same as the argument data type
9653       </entry>
9654       <entry>the average (arithmetic mean) of all input values</entry>
9655      </row>
9656
9657      <row>
9658       <entry>
9659        <indexterm>
9660         <primary>bit_and</primary>
9661        </indexterm>
9662        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
9663       </entry>
9664       <entry>
9665        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9666        <type>bit</type>
9667       </entry>
9668       <entry>
9669         same as argument data type
9670       </entry>
9671       <entry>the bitwise AND of all non-null input values, or null if none</entry>
9672      </row>
9673
9674      <row>
9675       <entry>
9676        <indexterm>
9677         <primary>bit_or</primary>
9678        </indexterm>
9679        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
9680       </entry>
9681       <entry>
9682        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9683        <type>bit</type>
9684       </entry>
9685       <entry>
9686         same as argument data type
9687       </entry>
9688       <entry>the bitwise OR of all non-null input values, or null if none</entry>
9689      </row>
9690
9691      <row>
9692       <entry>
9693        <indexterm>
9694         <primary>bool_and</primary>
9695        </indexterm>
9696        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
9697       </entry>
9698       <entry>
9699        <type>bool</type>
9700       </entry>
9701       <entry>
9702        <type>bool</type>
9703       </entry>
9704       <entry>true if all input values are true, otherwise false</entry>
9705      </row>
9706
9707      <row>
9708       <entry>
9709        <indexterm>
9710         <primary>bool_or</primary>
9711        </indexterm>
9712        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
9713       </entry>
9714       <entry>
9715        <type>bool</type>
9716       </entry>
9717       <entry>
9718        <type>bool</type>
9719       </entry>
9720       <entry>true if at least one input value is true, otherwise false</entry>
9721      </row>
9722
9723      <row>
9724       <entry><function>count(*)</function></entry>
9725       <entry></entry>
9726       <entry><type>bigint</type></entry>
9727       <entry>number of input rows</entry>
9728      </row>
9729
9730      <row>
9731       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
9732       <entry>any</entry>
9733       <entry><type>bigint</type></entry>
9734       <entry>
9735        number of input rows for which the value of <replaceable
9736        class="parameter">expression</replaceable> is not null
9737       </entry>
9738      </row>
9739
9740      <row>
9741       <entry>
9742        <indexterm>
9743         <primary>every</primary>
9744        </indexterm>
9745        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
9746       </entry>
9747       <entry>
9748        <type>bool</type>
9749       </entry>
9750       <entry>
9751        <type>bool</type>
9752       </entry>
9753       <entry>equivalent to <function>bool_and</function></entry>
9754      </row>
9755
9756      <row>
9757       <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
9758       <entry>any array, numeric, string, or date/time type</entry>
9759       <entry>same as argument type</entry>
9760       <entry>
9761        maximum value of <replaceable
9762        class="parameter">expression</replaceable> across all input
9763        values
9764       </entry>
9765      </row>
9766
9767      <row>
9768       <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
9769       <entry>any array, numeric, string, or date/time type</entry>
9770       <entry>same as argument type</entry>
9771       <entry>
9772        minimum value of <replaceable
9773        class="parameter">expression</replaceable> across all input
9774        values
9775       </entry>
9776      </row>
9777
9778      <row>
9779       <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></entry>
9780       <entry>
9781        <type>smallint</type>, <type>int</type>,
9782        <type>bigint</type>, <type>real</type>, <type>double
9783        precision</type>, <type>numeric</type>, or
9784        <type>interval</type>
9785       </entry>
9786       <entry>
9787        <type>bigint</type> for <type>smallint</type> or
9788        <type>int</type> arguments, <type>numeric</type> for
9789        <type>bigint</type> arguments, <type>double precision</type>
9790        for floating-point arguments, otherwise the same as the
9791        argument data type
9792       </entry>
9793       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
9794      </row>
9795
9796      <row>
9797       <entry>
9798        <indexterm>
9799         <primary>xmlagg</primary>
9800        </indexterm>
9801        <function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
9802       </entry>
9803       <entry>
9804        <type>xml</type>
9805       </entry>
9806       <entry>
9807        <type>xml</type>
9808       </entry>
9809       <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
9810      </row>
9811     </tbody>
9812    </tgroup>
9813   </table>
9814
9815   <para>
9816    It should be noted that except for <function>count</function>,
9817    these functions return a null value when no rows are selected.  In
9818    particular, <function>sum</function> of no rows returns null, not
9819    zero as one might expect, and <function>array_agg</function>
9820    returns null rather than an empty array when there are no input
9821    rows.  The <function>coalesce</function> function can be used to
9822    substitute zero or an empty array for null when necessary.
9823   </para>
9824
9825   <note>
9826     <indexterm>
9827       <primary>ANY</primary>
9828     </indexterm>
9829     <indexterm>
9830       <primary>SOME</primary>
9831     </indexterm>
9832     <para>
9833       Boolean aggregates <function>bool_and</function> and
9834       <function>bool_or</function> correspond to standard SQL aggregates
9835       <function>every</function> and <function>any</function> or
9836       <function>some</function>.
9837       As for <function>any</function> and <function>some</function>,
9838       it seems that there is an ambiguity built into the standard syntax:
9839 <programlisting>
9840 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
9841 </programlisting>
9842       Here <function>ANY</function> can be considered either as introducing
9843       a subquery, or as being an aggregate function, if the sub-select
9844       returns one row with a boolean value.
9845       Thus the standard name cannot be given to these aggregates.
9846     </para>
9847   </note>
9848
9849   <note>
9850    <para>
9851     Users accustomed to working with other SQL database management
9852     systems might be disappointed by the performance of the
9853     <function>count</function> aggregate when it is applied to the
9854     entire table. A query like:
9855 <programlisting>
9856 SELECT count(*) FROM sometable;
9857 </programlisting>
9858     will be executed by <productname>PostgreSQL</productname> using a
9859     sequential scan of the entire table.
9860    </para>
9861   </note>
9862
9863   <para>
9864    The aggregate functions <function>array_agg</function>
9865    and <function>xmlagg</function>, as well as similar user-defined
9866    aggregate functions, produce meaningfully different result values
9867    depending on the order of the input values.  In the current
9868    implementation, the order of the input is in principle unspecified.
9869    Supplying the input values from a sorted subquery
9870    will usually work, however.  For example:
9871
9872 <screen><![CDATA[
9873 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
9874 ]]></screen>
9875
9876    But this syntax is not allowed in the SQL standard, and is
9877    not portable to other database systems.  A future version of
9878    <productname>PostgreSQL</> might provide an additional feature to control
9879    the order in a better-defined way (<literal>xmlagg(expr ORDER BY expr, expr,
9880    ...)</literal>).
9881   </para>
9882
9883   <para>
9884    <xref linkend="functions-aggregate-statistics-table"> shows
9885    aggregate functions typically used in statistical analysis.
9886    (These are separated out merely to avoid cluttering the listing
9887    of more-commonly-used aggregates.)  Where the description mentions
9888    <replaceable class="parameter">N</replaceable>, it means the
9889    number of input rows for which all the input expressions are non-null.
9890    In all cases, null is returned if the computation is meaningless,
9891    for example when <replaceable class="parameter">N</replaceable> is zero.
9892   </para>
9893
9894   <indexterm>
9895    <primary>statistics</primary>
9896   </indexterm>
9897   <indexterm>
9898    <primary>linear regression</primary>
9899   </indexterm>
9900
9901   <table id="functions-aggregate-statistics-table">
9902    <title>Aggregate Functions for Statistics</title>
9903
9904    <tgroup cols="4">
9905     <thead>
9906      <row>
9907       <entry>Function</entry>
9908       <entry>Argument Type</entry>
9909       <entry>Return Type</entry>
9910       <entry>Description</entry>
9911      </row>
9912     </thead>
9913
9914     <tbody>
9915
9916      <row>
9917       <entry>
9918        <indexterm>
9919         <primary>correlation</primary>
9920        </indexterm>
9921        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9922       </entry>
9923       <entry>
9924        <type>double precision</type>
9925       </entry>
9926       <entry>
9927        <type>double precision</type>
9928       </entry>
9929       <entry>correlation coefficient</entry>
9930      </row>
9931
9932      <row>
9933       <entry>
9934        <indexterm>
9935         <primary>covariance</primary>
9936         <secondary>population</secondary>
9937        </indexterm>
9938        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9939       </entry>
9940       <entry>
9941        <type>double precision</type>
9942       </entry>
9943       <entry>
9944        <type>double precision</type>
9945       </entry>
9946       <entry>population covariance</entry>
9947      </row>
9948
9949      <row>
9950       <entry>
9951        <indexterm>
9952         <primary>covariance</primary>
9953         <secondary>sample</secondary>
9954        </indexterm>
9955        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9956       </entry>
9957       <entry>
9958        <type>double precision</type>
9959       </entry>
9960       <entry>
9961        <type>double precision</type>
9962       </entry>
9963       <entry>sample covariance</entry>
9964      </row>
9965
9966      <row>
9967       <entry>
9968        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9969       </entry>
9970       <entry>
9971        <type>double precision</type>
9972       </entry>
9973       <entry>
9974        <type>double precision</type>
9975       </entry>
9976       <entry>average of the independent variable
9977       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9978      </row>
9979
9980      <row>
9981       <entry>
9982        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9983       </entry>
9984       <entry>
9985        <type>double precision</type>
9986       </entry>
9987       <entry>
9988        <type>double precision</type>
9989       </entry>
9990       <entry>average of the dependent variable
9991       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
9992      </row>
9993
9994      <row>
9995       <entry>
9996        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
9997       </entry>
9998       <entry>
9999        <type>double precision</type>
10000       </entry>
10001       <entry>
10002        <type>bigint</type>
10003       </entry>
10004       <entry>number of input rows in which both expressions are nonnull</entry>
10005      </row>
10006
10007      <row>
10008       <entry>
10009        <indexterm>
10010         <primary>regression intercept</primary>
10011        </indexterm>
10012        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10013       </entry>
10014       <entry>
10015        <type>double precision</type>
10016       </entry>
10017       <entry>
10018        <type>double precision</type>
10019       </entry>
10020       <entry>y-intercept of the least-squares-fit linear equation
10021       determined by the (<replaceable
10022       class="parameter">X</replaceable>, <replaceable
10023       class="parameter">Y</replaceable>) pairs</entry>
10024      </row>
10025
10026      <row>
10027       <entry>
10028        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10029       </entry>
10030       <entry>
10031        <type>double precision</type>
10032       </entry>
10033       <entry>
10034        <type>double precision</type>
10035       </entry>
10036       <entry>square of the correlation coefficient</entry>
10037      </row>
10038
10039      <row>
10040       <entry>
10041        <indexterm>
10042         <primary>regression slope</primary>
10043        </indexterm>
10044        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10045       </entry>
10046       <entry>
10047        <type>double precision</type>
10048       </entry>
10049       <entry>
10050        <type>double precision</type>
10051       </entry>
10052       <entry>slope of the least-squares-fit linear equation determined
10053       by the (<replaceable class="parameter">X</replaceable>,
10054       <replaceable class="parameter">Y</replaceable>) pairs</entry>
10055      </row>
10056
10057      <row>
10058       <entry>
10059        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10060       </entry>
10061       <entry>
10062        <type>double precision</type>
10063       </entry>
10064       <entry>
10065        <type>double precision</type>
10066       </entry>
10067       <entry><literal>sum(<replaceable
10068       class="parameter">X</replaceable>^2) - sum(<replaceable
10069       class="parameter">X</replaceable>)^2/<replaceable
10070       class="parameter">N</replaceable></literal> (<quote>sum of
10071       squares</quote> of the independent variable)</entry>
10072      </row>
10073
10074      <row>
10075       <entry>
10076        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10077       </entry>
10078       <entry>
10079        <type>double precision</type>
10080       </entry>
10081       <entry>
10082        <type>double precision</type>
10083       </entry>
10084       <entry><literal>sum(<replaceable
10085       class="parameter">X</replaceable>*<replaceable
10086       class="parameter">Y</replaceable>) - sum(<replaceable
10087       class="parameter">X</replaceable>) * sum(<replaceable
10088       class="parameter">Y</replaceable>)/<replaceable
10089       class="parameter">N</replaceable></literal> (<quote>sum of
10090       products</quote> of independent times dependent
10091       variable)</entry>
10092      </row>
10093
10094      <row>
10095       <entry>
10096        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10097       </entry>
10098       <entry>
10099        <type>double precision</type>
10100       </entry>
10101       <entry>
10102        <type>double precision</type>
10103       </entry>
10104       <entry><literal>sum(<replaceable
10105       class="parameter">Y</replaceable>^2) - sum(<replaceable
10106       class="parameter">Y</replaceable>)^2/<replaceable
10107       class="parameter">N</replaceable></literal> (<quote>sum of
10108       squares</quote> of the dependent variable)</entry>
10109      </row>
10110
10111      <row>
10112       <entry>
10113        <indexterm>
10114         <primary>standard deviation</primary>
10115        </indexterm>
10116        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
10117       </entry>
10118       <entry>
10119        <type>smallint</type>, <type>int</type>,
10120        <type>bigint</type>, <type>real</type>, <type>double
10121        precision</type>, or <type>numeric</type>
10122       </entry>
10123       <entry>
10124        <type>double precision</type> for floating-point arguments,
10125        otherwise <type>numeric</type>
10126       </entry>
10127       <entry>historical alias for <function>stddev_samp</function></entry>
10128      </row>
10129
10130      <row>
10131       <entry>
10132        <indexterm>
10133         <primary>standard deviation</primary>
10134         <secondary>population</secondary>
10135        </indexterm>
10136        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
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>population standard deviation of the input values</entry>
10148      </row>
10149
10150      <row>
10151       <entry>
10152        <indexterm>
10153         <primary>standard deviation</primary>
10154         <secondary>sample</secondary>
10155        </indexterm>
10156        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
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>sample standard deviation of the input values</entry>
10168      </row>
10169
10170      <row>
10171       <entry>
10172        <indexterm>
10173         <primary>variance</primary>
10174        </indexterm>
10175        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
10176       </entry>
10177       <entry>
10178        <type>smallint</type>, <type>int</type>,
10179        <type>bigint</type>, <type>real</type>, <type>double
10180        precision</type>, or <type>numeric</type>
10181       </entry>
10182       <entry>
10183        <type>double precision</type> for floating-point arguments,
10184        otherwise <type>numeric</type>
10185       </entry>
10186       <entry>historical alias for <function>var_samp</function></entry>
10187      </row>
10188
10189      <row>
10190       <entry>
10191        <indexterm>
10192         <primary>variance</primary>
10193         <secondary>population</secondary>
10194        </indexterm>
10195        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
10196       </entry>
10197       <entry>
10198        <type>smallint</type>, <type>int</type>,
10199        <type>bigint</type>, <type>real</type>, <type>double
10200        precision</type>, or <type>numeric</type>
10201       </entry>
10202       <entry>
10203        <type>double precision</type> for floating-point arguments,
10204        otherwise <type>numeric</type>
10205       </entry>
10206       <entry>population variance of the input values (square of the population standard deviation)</entry>
10207      </row>
10208
10209      <row>
10210       <entry>
10211        <indexterm>
10212         <primary>variance</primary>
10213         <secondary>sample</secondary>
10214        </indexterm>
10215        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
10216       </entry>
10217       <entry>
10218        <type>smallint</type>, <type>int</type>,
10219        <type>bigint</type>, <type>real</type>, <type>double
10220        precision</type>, or <type>numeric</type>
10221       </entry>
10222       <entry>
10223        <type>double precision</type> for floating-point arguments,
10224        otherwise <type>numeric</type>
10225       </entry>
10226       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
10227      </row>
10228     </tbody>
10229    </tgroup>
10230   </table>
10231
10232  </sect1>
10233
10234  <sect1 id="functions-window">
10235   <title>Window Functions</title>
10236
10237   <indexterm zone="functions-window">
10238    <primary>window function</primary>
10239    <secondary>built-in</secondary>
10240   </indexterm>
10241
10242   <para>
10243    <firstterm>Window functions</firstterm> provide the ability to perform
10244    calculations across sets of rows that are related to the current query
10245    row.  See <xref linkend="tutorial-window"> for an introduction to this
10246    feature.
10247   </para>
10248
10249   <para>
10250    The built-in window functions are listed in
10251    <xref linkend="functions-window-table">.  Note that these functions
10252    <emphasis>must</> be invoked using window function syntax; that is an
10253    <literal>OVER</> clause is required.
10254   </para>
10255
10256   <para>
10257    In addition to these functions, any built-in or user-defined aggregate
10258    function can be used as a window function (see
10259    <xref linkend="functions-aggregate"> for a list of the built-in aggregates).
10260    Aggregate functions act as window functions only when an <literal>OVER</>
10261    clause follows the call; otherwise they act as regular aggregates.
10262   </para>
10263
10264   <table id="functions-window-table">
10265    <title>General-Purpose Window Functions</title>
10266
10267    <tgroup cols="3">
10268     <thead>
10269      <row>
10270       <entry>Function</entry>
10271       <entry>Return Type</entry>
10272       <entry>Description</entry>
10273      </row>
10274     </thead>
10275
10276     <tbody>
10277      <row>
10278       <entry>
10279        <indexterm>
10280         <primary>row_number</primary>
10281        </indexterm>
10282        <function>row_number()</function>
10283       </entry>
10284       <entry>
10285        <type>bigint</type>
10286       </entry>
10287       <entry>number of the current row within its partition, counting from 1</entry>
10288      </row>
10289
10290      <row>
10291       <entry>
10292        <indexterm>
10293         <primary>rank</primary>
10294        </indexterm>
10295        <function>rank()</function>
10296       </entry>
10297       <entry>
10298        <type>bigint</type>
10299       </entry>
10300       <entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
10301      </row>
10302
10303      <row>
10304       <entry>
10305        <indexterm>
10306         <primary>dense_rank</primary>
10307        </indexterm>
10308        <function>dense_rank()</function>
10309       </entry>
10310       <entry>
10311        <type>bigint</type>
10312       </entry>
10313       <entry>rank of the current row without gaps; this function counts peer groups</entry>
10314      </row>
10315
10316      <row>
10317       <entry>
10318        <indexterm>
10319         <primary>percent_rank</primary>
10320        </indexterm>
10321        <function>percent_rank()</function>
10322       </entry>
10323       <entry>
10324        <type>double precision</type>
10325       </entry>
10326       <entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
10327      </row>
10328
10329      <row>
10330       <entry>
10331        <indexterm>
10332         <primary>cume_dist</primary>
10333        </indexterm>
10334        <function>cume_dist()</function>
10335       </entry>
10336       <entry>
10337        <type>double precision</type>
10338       </entry>
10339       <entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
10340      </row>
10341
10342      <row>
10343       <entry>
10344        <indexterm>
10345         <primary>ntile</primary>
10346        </indexterm>
10347        <function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</>)</function>
10348       </entry>
10349       <entry>
10350        <type>integer</type>
10351       </entry>
10352       <entry>integer ranging from 1 to the argument value, dividing the
10353        partition as equally as possible</entry>
10354      </row>
10355
10356      <row>
10357       <entry>
10358        <indexterm>
10359         <primary>lag</primary>
10360        </indexterm>
10361        <function>
10362          lag(<replaceable class="parameter">value</replaceable> <type>any</>
10363              [, <replaceable class="parameter">offset</replaceable> <type>integer</>
10364              [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
10365        </function>
10366       </entry>
10367       <entry>
10368        <type>same type as <replaceable class="parameter">value</replaceable></type>
10369       </entry>
10370       <entry>
10371        returns <replaceable class="parameter">value</replaceable> evaluated at
10372        the row that is <replaceable class="parameter">offset</replaceable>
10373        rows before the current row within the partition; if there is no such
10374        row, instead return <replaceable class="parameter">default</replaceable>.
10375        Both <replaceable class="parameter">offset</replaceable> and
10376        <replaceable class="parameter">default</replaceable> are evaluated
10377        with respect to the current row.  If omitted,
10378        <replaceable class="parameter">offset</replaceable> defaults to 1 and
10379        <replaceable class="parameter">default</replaceable> to null
10380       </entry>
10381      </row>
10382
10383      <row>
10384       <entry>
10385        <indexterm>
10386         <primary>lead</primary>
10387        </indexterm>
10388        <function>
10389          lead(<replaceable class="parameter">value</replaceable> <type>any</>
10390               [, <replaceable class="parameter">offset</replaceable> <type>integer</>
10391               [, <replaceable class="parameter">default</replaceable> <type>any</> ]])
10392        </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 at
10399        the row that is <replaceable class="parameter">offset</replaceable>
10400        rows after the current row within the partition; if there is no such
10401        row, instead return <replaceable class="parameter">default</replaceable>.
10402        Both <replaceable class="parameter">offset</replaceable> and
10403        <replaceable class="parameter">default</replaceable> are evaluated
10404        with respect to the current row.  If omitted,
10405        <replaceable class="parameter">offset</replaceable> defaults to 1 and
10406        <replaceable class="parameter">default</replaceable> to null
10407       </entry>
10408      </row>
10409
10410      <row>
10411       <entry>
10412        <indexterm>
10413         <primary>first_value</primary>
10414        </indexterm>
10415        <function>first_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
10416       </entry>
10417       <entry>
10418        <type>same type as <replaceable class="parameter">value</replaceable></type>
10419       </entry>
10420       <entry>
10421        returns <replaceable class="parameter">value</replaceable> evaluated
10422        at the row that is the first row of the window frame
10423       </entry>
10424      </row>
10425
10426      <row>
10427       <entry>
10428        <indexterm>
10429         <primary>last_value</primary>
10430        </indexterm>
10431        <function>last_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
10432       </entry>
10433       <entry>
10434        <type>same type as <replaceable class="parameter">value</replaceable></type>
10435       </entry>
10436       <entry>
10437        returns <replaceable class="parameter">value</replaceable> evaluated
10438        at the row that is the last row of the window frame
10439       </entry>
10440      </row>
10441
10442      <row>
10443       <entry>
10444        <indexterm>
10445         <primary>nth_value</primary>
10446        </indexterm>
10447        <function>
10448          nth_value(<replaceable class="parameter">value</replaceable> <type>any</>, <replaceable class="parameter">nth</replaceable> <type>integer</>)
10449        </function>
10450       </entry>
10451       <entry>
10452        <type>same type as <replaceable class="parameter">value</replaceable></type>
10453       </entry>
10454       <entry>
10455        returns <replaceable class="parameter">value</replaceable> evaluated
10456        at the row that is the <replaceable class="parameter">nth</replaceable>
10457        row of the window frame (counting from 1); null if no such row
10458       </entry>
10459      </row>
10460     </tbody>
10461    </tgroup>
10462   </table>
10463
10464   <para>
10465    All of the functions listed in
10466    <xref linkend="functions-window-table"> depend on the sort ordering
10467    specified by the <literal>ORDER BY</> clause of the associated window
10468    definition.  Rows that are not distinct in the <literal>ORDER BY</>
10469    ordering are said to be <firstterm>peers</>; the four ranking functions
10470    are defined so that they give the same answer for any two peer rows.
10471   </para>
10472
10473   <para>
10474    Note that <function>first_value</>, <function>last_value</>, and
10475    <function>nth_value</> consider only the rows within the <quote>window
10476    frame</>, which by default contains the rows from the start of the
10477    partition through the last peer of the current row.  This is
10478    likely to give unhelpful results for <function>nth_value</> and
10479    particularly <function>last_value</>.  You can redefine the frame as
10480    being the whole partition by adding <literal>ROWS BETWEEN UNBOUNDED
10481    PRECEDING AND UNBOUNDED FOLLOWING</> to the <literal>OVER</> clause.
10482    See <xref linkend="syntax-window-functions"> for more information.
10483   </para>
10484
10485   <para>
10486    When an aggregate function is used as a window function, it aggregates
10487    over the rows within the current row's window frame.  To obtain
10488    aggregation over the whole partition, omit <literal>ORDER BY</> or use
10489    <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
10490    An aggregate used with <literal>ORDER BY</> and the default window frame
10491    definition produces a <quote>running sum</> type of behavior, which may or
10492    may not be what's wanted.
10493   </para>
10494
10495   <note>
10496    <para>
10497     The SQL standard defines a <literal>RESPECT NULLS</> or
10498     <literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
10499     <function>first_value</>, <function>last_value</>, and
10500     <function>nth_value</>.  This is not implemented in
10501     <productname>PostgreSQL</productname>: the behavior is always the
10502     same as the standard's default, namely <literal>RESPECT NULLS</>.
10503     Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
10504     option for <function>nth_value</> is not implemented: only the
10505     default <literal>FROM FIRST</> behavior is supported.  (You can achieve
10506     the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
10507     ordering.)
10508    </para>
10509   </note>
10510
10511  </sect1>
10512
10513  <sect1 id="functions-subquery">
10514   <title>Subquery Expressions</title>
10515
10516   <indexterm>
10517    <primary>EXISTS</primary>
10518   </indexterm>
10519
10520   <indexterm>
10521    <primary>IN</primary>
10522   </indexterm>
10523
10524   <indexterm>
10525    <primary>NOT IN</primary>
10526   </indexterm>
10527
10528   <indexterm>
10529    <primary>ANY</primary>
10530   </indexterm>
10531
10532   <indexterm>
10533    <primary>ALL</primary>
10534   </indexterm>
10535
10536   <indexterm>
10537    <primary>SOME</primary>
10538   </indexterm>
10539
10540   <indexterm>
10541    <primary>subquery</primary>
10542   </indexterm>
10543
10544   <para>
10545    This section describes the <acronym>SQL</acronym>-compliant subquery
10546    expressions available in <productname>PostgreSQL</productname>.
10547    All of the expression forms documented in this section return
10548    Boolean (true/false) results.
10549   </para>
10550
10551   <sect2>
10552    <title><literal>EXISTS</literal></title>
10553
10554 <synopsis>
10555 EXISTS (<replaceable>subquery</replaceable>)
10556 </synopsis>
10557
10558   <para>
10559    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
10560    or <firstterm>subquery</firstterm>.  The
10561    subquery is evaluated to determine whether it returns any rows.
10562    If it returns at least one row, the result of <token>EXISTS</token> is
10563    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
10564    is <quote>false</>.
10565   </para>
10566
10567   <para>
10568    The subquery can refer to variables from the surrounding query,
10569    which will act as constants during any one evaluation of the subquery.
10570   </para>
10571
10572   <para>
10573    The subquery will generally only be executed long enough to determine
10574    whether at least one row is returned, not all the way to completion.
10575    It is unwise to write a subquery that has side effects (such as
10576    calling sequence functions); whether the side effects occur
10577    might be unpredictable.
10578   </para>
10579
10580   <para>
10581    Since the result depends only on whether any rows are returned,
10582    and not on the contents of those rows, the output list of the
10583    subquery is normally unimportant.  A common coding convention is
10584    to write all <literal>EXISTS</> tests in the form
10585    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
10586    this rule however, such as subqueries that use <token>INTERSECT</token>.
10587   </para>
10588
10589   <para>
10590    This simple example is like an inner join on <literal>col2</>, but
10591    it produces at most one output row for each <literal>tab1</> row,
10592    even if there are several matching <literal>tab2</> rows:
10593 <screen>
10594 SELECT col1
10595 FROM tab1
10596 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
10597 </screen>
10598   </para>
10599   </sect2>
10600
10601   <sect2>
10602    <title><literal>IN</literal></title>
10603
10604 <synopsis>
10605 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
10606 </synopsis>
10607
10608   <para>
10609    The right-hand side is a parenthesized
10610    subquery, which must return exactly one column.  The left-hand expression
10611    is evaluated and compared to each row of the subquery result.
10612    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10613    The result is <quote>false</> if no equal row is found (including the
10614    case where the subquery returns no rows).
10615   </para>
10616
10617   <para>
10618    Note that if the left-hand expression yields null, or if there are
10619    no equal right-hand values and at least one right-hand row yields
10620    null, the result of the <token>IN</token> construct will be null, not false.
10621    This is in accordance with SQL's normal rules for Boolean combinations
10622    of null values.
10623   </para>
10624
10625   <para>
10626    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10627    be evaluated completely.
10628   </para>
10629
10630 <synopsis>
10631 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
10632 </synopsis>
10633
10634   <para>
10635    The left-hand side of this form of <token>IN</token> is a row constructor,
10636    as described in <xref linkend="sql-syntax-row-constructors">.
10637    The right-hand side is a parenthesized
10638    subquery, which must return exactly as many columns as there are
10639    expressions in the left-hand row.  The left-hand expressions are
10640    evaluated and compared row-wise to each row of the subquery result.
10641    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10642    The result is <quote>false</> if no equal row is found (including the
10643    case where the subquery returns no rows).
10644   </para>
10645
10646   <para>
10647    As usual, null values in the rows are combined per
10648    the normal rules of SQL Boolean expressions.  Two rows are considered
10649    equal if all their corresponding members are non-null and equal; the rows
10650    are unequal if any corresponding members are non-null and unequal;
10651    otherwise the result of that row comparison is unknown (null).
10652    If all the per-row results are either unequal or null, with at least one
10653    null, then the result of <token>IN</token> is null.
10654   </para>
10655   </sect2>
10656
10657   <sect2>
10658    <title><literal>NOT IN</literal></title>
10659
10660 <synopsis>
10661 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10662 </synopsis>
10663
10664   <para>
10665    The right-hand side is a parenthesized
10666    subquery, which must return exactly one column.  The left-hand expression
10667    is evaluated and compared to each row of the subquery result.
10668    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10669    are found (including the case where the subquery returns no rows).
10670    The result is <quote>false</> if any equal row is found.
10671   </para>
10672
10673   <para>
10674    Note that if the left-hand expression yields null, or if there are
10675    no equal right-hand values and at least one right-hand row yields
10676    null, the result of the <token>NOT IN</token> construct will be null, not true.
10677    This is in accordance with SQL's normal rules for Boolean combinations
10678    of null values.
10679   </para>
10680
10681   <para>
10682    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10683    be evaluated completely.
10684   </para>
10685
10686 <synopsis>
10687 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10688 </synopsis>
10689
10690   <para>
10691    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
10692    as described in <xref linkend="sql-syntax-row-constructors">.
10693    The right-hand side is a parenthesized
10694    subquery, which must return exactly as many columns as there are
10695    expressions in the left-hand row.  The left-hand expressions are
10696    evaluated and compared row-wise to each row of the subquery result.
10697    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10698    are found (including the case where the subquery returns no rows).
10699    The result is <quote>false</> if any equal row is found.
10700   </para>
10701
10702   <para>
10703    As usual, null values in the rows are combined per
10704    the normal rules of SQL Boolean expressions.  Two rows are considered
10705    equal if all their corresponding members are non-null and equal; the rows
10706    are unequal if any corresponding members are non-null and unequal;
10707    otherwise the result of that row comparison is unknown (null).
10708    If all the per-row results are either unequal or null, with at least one
10709    null, then the result of <token>NOT IN</token> is null.
10710   </para>
10711   </sect2>
10712
10713   <sect2>
10714    <title><literal>ANY</literal>/<literal>SOME</literal></title>
10715
10716 <synopsis>
10717 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
10718 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
10719 </synopsis>
10720
10721   <para>
10722    The right-hand side is a parenthesized
10723    subquery, which must return exactly one column.  The left-hand expression
10724    is evaluated and compared to each row of the subquery result using the
10725    given <replaceable>operator</replaceable>, which must yield a Boolean
10726    result.
10727    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10728    The result is <quote>false</> if no true result is found (including the
10729    case where the subquery returns no rows).
10730   </para>
10731
10732   <para>
10733    <token>SOME</token> is a synonym for <token>ANY</token>.
10734    <token>IN</token> is equivalent to <literal>= ANY</literal>.
10735   </para>
10736
10737   <para>
10738    Note that if there are no successes and at least one right-hand row yields
10739    null for the operator's result, the result of the <token>ANY</token> construct
10740    will be null, not false.
10741    This is in accordance with SQL's normal rules for Boolean combinations
10742    of null values.
10743   </para>
10744
10745   <para>
10746    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10747    be evaluated completely.
10748   </para>
10749
10750 <synopsis>
10751 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
10752 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
10753 </synopsis>
10754
10755   <para>
10756    The left-hand side of this form of <token>ANY</token> is a row constructor,
10757    as described in <xref linkend="sql-syntax-row-constructors">.
10758    The right-hand side is a parenthesized
10759    subquery, which must return exactly as many columns as there are
10760    expressions in the left-hand row.  The left-hand expressions are
10761    evaluated and compared row-wise to each row of the subquery result,
10762    using the given <replaceable>operator</replaceable>.
10763    The result of <token>ANY</token> is <quote>true</> if the comparison
10764    returns true for any subquery row.
10765    The result is <quote>false</> if the comparison returns false for every
10766    subquery row (including the case where the subquery returns no
10767    rows).
10768    The result is NULL if the comparison does not return true for any row,
10769    and it returns NULL for at least one row.
10770   </para>
10771
10772   <para>
10773    See <xref linkend="row-wise-comparison"> for details about the meaning
10774    of a row-wise comparison.
10775   </para>
10776   </sect2>
10777
10778   <sect2>
10779    <title><literal>ALL</literal></title>
10780
10781 <synopsis>
10782 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10783 </synopsis>
10784
10785   <para>
10786    The right-hand side is a parenthesized
10787    subquery, which must return exactly one column.  The left-hand expression
10788    is evaluated and compared to each row of the subquery result using the
10789    given <replaceable>operator</replaceable>, which must yield a Boolean
10790    result.
10791    The result of <token>ALL</token> is <quote>true</> if all rows yield true
10792    (including the case where the subquery returns no rows).
10793    The result is <quote>false</> if any false result is found.
10794    The result is NULL if the comparison does not return false for any row,
10795    and it returns NULL for at least one row.
10796   </para>
10797
10798   <para>
10799    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
10800   </para>
10801
10802   <para>
10803    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10804    be evaluated completely.
10805   </para>
10806
10807 <synopsis>
10808 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10809 </synopsis>
10810
10811   <para>
10812    The left-hand side of this form of <token>ALL</token> is a row constructor,
10813    as described in <xref linkend="sql-syntax-row-constructors">.
10814    The right-hand side is a parenthesized
10815    subquery, which must return exactly as many columns as there are
10816    expressions in the left-hand row.  The left-hand expressions are
10817    evaluated and compared row-wise to each row of the subquery result,
10818    using the given <replaceable>operator</replaceable>.
10819    The result of <token>ALL</token> is <quote>true</> if the comparison
10820    returns true for all subquery rows (including the
10821    case where the subquery returns no rows).
10822    The result is <quote>false</> if the comparison returns false for any
10823    subquery row.
10824    The result is NULL if the comparison does not return false for any
10825    subquery row, and it returns NULL for at least one row.
10826   </para>
10827
10828   <para>
10829    See <xref linkend="row-wise-comparison"> for details about the meaning
10830    of a row-wise comparison.
10831   </para>
10832   </sect2>
10833
10834   <sect2>
10835    <title>Row-wise Comparison</title>
10836
10837    <indexterm zone="functions-subquery">
10838     <primary>comparison</primary>
10839     <secondary>subquery result row</secondary>
10840    </indexterm>
10841
10842 <synopsis>
10843 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
10844 </synopsis>
10845
10846   <para>
10847    The left-hand side is a row constructor,
10848    as described in <xref linkend="sql-syntax-row-constructors">.
10849    The right-hand side is a parenthesized subquery, which must return exactly
10850    as many columns as there are expressions in the left-hand row. Furthermore,
10851    the subquery cannot return more than one row.  (If it returns zero rows,
10852    the result is taken to be null.)  The left-hand side is evaluated and
10853    compared row-wise to the single subquery result row.
10854   </para>
10855
10856   <para>
10857    See <xref linkend="row-wise-comparison"> for details about the meaning
10858    of a row-wise comparison.
10859   </para>
10860   </sect2>
10861  </sect1>
10862
10863
10864  <sect1 id="functions-comparisons">
10865   <title>Row and Array Comparisons</title>
10866
10867   <indexterm>
10868    <primary>IN</primary>
10869   </indexterm>
10870
10871   <indexterm>
10872    <primary>NOT IN</primary>
10873   </indexterm>
10874
10875   <indexterm>
10876    <primary>ANY</primary>
10877   </indexterm>
10878
10879   <indexterm>
10880    <primary>ALL</primary>
10881   </indexterm>
10882
10883   <indexterm>
10884    <primary>SOME</primary>
10885   </indexterm>
10886
10887   <indexterm>
10888    <primary>row-wise comparison</primary>
10889   </indexterm>
10890
10891   <indexterm>
10892    <primary>comparison</primary>
10893    <secondary>row-wise</secondary>
10894   </indexterm>
10895
10896   <indexterm>
10897    <primary>IS DISTINCT FROM</primary>
10898   </indexterm>
10899
10900   <indexterm>
10901    <primary>IS NOT DISTINCT FROM</primary>
10902   </indexterm>
10903
10904   <para>
10905    This section describes several specialized constructs for making
10906    multiple comparisons between groups of values.  These forms are
10907    syntactically related to the subquery forms of the previous section,
10908    but do not involve subqueries.
10909    The forms involving array subexpressions are
10910    <productname>PostgreSQL</productname> extensions; the rest are
10911    <acronym>SQL</acronym>-compliant.
10912    All of the expression forms documented in this section return
10913    Boolean (true/false) results.
10914   </para>
10915
10916   <sect2>
10917    <title><literal>IN</literal></title>
10918
10919 <synopsis>
10920 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10921 </synopsis>
10922
10923   <para>
10924    The right-hand side is a parenthesized list
10925    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
10926    result is equal to any of the right-hand expressions.  This is a shorthand
10927    notation for
10928
10929 <synopsis>
10930 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
10931 OR
10932 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
10933 OR
10934 ...
10935 </synopsis>
10936   </para>
10937
10938   <para>
10939    Note that if the left-hand expression yields null, or if there are
10940    no equal right-hand values and at least one right-hand expression yields
10941    null, the result of the <token>IN</token> construct will be null, not false.
10942    This is in accordance with SQL's normal rules for Boolean combinations
10943    of null values.
10944   </para>
10945   </sect2>
10946
10947   <sect2>
10948    <title><literal>NOT IN</literal></title>
10949
10950 <synopsis>
10951 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10952 </synopsis>
10953
10954   <para>
10955    The right-hand side is a parenthesized list
10956    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
10957    result is unequal to all of the right-hand expressions.  This is a shorthand
10958    notation for
10959
10960 <synopsis>
10961 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
10962 AND
10963 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
10964 AND
10965 ...
10966 </synopsis>
10967   </para>
10968
10969   <para>
10970    Note that if the left-hand expression yields null, or if there are
10971    no equal right-hand values and at least one right-hand expression yields
10972    null, the result of the <token>NOT IN</token> construct will be null, not true
10973    as one might naively expect.
10974    This is in accordance with SQL's normal rules for Boolean combinations
10975    of null values.
10976   </para>
10977
10978   <tip>
10979   <para>
10980    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
10981    cases.  However, null values are much more likely to trip up the novice when
10982    working with <token>NOT IN</token> than when working with <token>IN</token>.
10983    It is best to express your condition positively if possible.
10984   </para>
10985   </tip>
10986   </sect2>
10987
10988   <sect2>
10989    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
10990
10991 <synopsis>
10992 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
10993 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
10994 </synopsis>
10995
10996   <para>
10997    The right-hand side is a parenthesized expression, which must yield an
10998    array value.
10999    The left-hand expression
11000    is evaluated and compared to each element of the array using the
11001    given <replaceable>operator</replaceable>, which must yield a Boolean
11002    result.
11003    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
11004    The result is <quote>false</> if no true result is found (including the
11005    case where the array has zero elements).
11006   </para>
11007
11008   <para>
11009    If the array expression yields a null array, the result of
11010    <token>ANY</token> will be null.  If the left-hand expression yields null,
11011    the result of <token>ANY</token> is ordinarily null (though a non-strict
11012    comparison operator could possibly yield a different result).
11013    Also, if the right-hand array contains any null elements and no true
11014    comparison result is obtained, the result of <token>ANY</token>
11015    will be null, not false (again, assuming a strict comparison operator).
11016    This is in accordance with SQL's normal rules for Boolean combinations
11017    of null values.
11018   </para>
11019
11020   <para>
11021    <token>SOME</token> is a synonym for <token>ANY</token>.
11022   </para>
11023   </sect2>
11024
11025   <sect2>
11026    <title><literal>ALL</literal> (array)</title>
11027
11028 <synopsis>
11029 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
11030 </synopsis>
11031
11032   <para>
11033    The right-hand side is a parenthesized expression, which must yield an
11034    array value.
11035    The left-hand expression
11036    is evaluated and compared to each element of the array using the
11037    given <replaceable>operator</replaceable>, which must yield a Boolean
11038    result.
11039    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
11040    (including the case where the array has zero elements).
11041    The result is <quote>false</> if any false result is found.
11042   </para>
11043
11044   <para>
11045    If the array expression yields a null array, the result of
11046    <token>ALL</token> will be null.  If the left-hand expression yields null,
11047    the result of <token>ALL</token> is ordinarily null (though a non-strict
11048    comparison operator could possibly yield a different result).
11049    Also, if the right-hand array contains any null elements and no false
11050    comparison result is obtained, the result of <token>ALL</token>
11051    will be null, not true (again, assuming a strict comparison operator).
11052    This is in accordance with SQL's normal rules for Boolean combinations
11053    of null values.
11054   </para>
11055   </sect2>
11056
11057   <sect2 id="row-wise-comparison">
11058    <title>Row-wise Comparison</title>
11059
11060 <synopsis>
11061 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
11062 </synopsis>
11063
11064   <para>
11065    Each side is a row constructor,
11066    as described in <xref linkend="sql-syntax-row-constructors">.
11067    The two row values must have the same number of fields.
11068    Each side is evaluated and they are compared row-wise.  Row comparisons
11069    are allowed when the <replaceable>operator</replaceable> is
11070    <literal>=</>,
11071    <literal>&lt;&gt;</>,
11072    <literal>&lt;</>,
11073    <literal>&lt;=</>,
11074    <literal>&gt;</> or
11075    <literal>&gt;=</>,
11076    or has semantics similar to one of these.  (To be specific, an operator
11077    can be a row comparison operator if it is a member of a B-Tree operator
11078    class, or is the negator of the <literal>=</> member of a B-Tree operator
11079    class.)
11080   </para>
11081
11082   <para>
11083    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
11084    from the others.  Two rows are considered
11085    equal if all their corresponding members are non-null and equal; the rows
11086    are unequal if any corresponding members are non-null and unequal;
11087    otherwise the result of the row comparison is unknown (null).
11088   </para>
11089
11090   <para>
11091    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
11092    <literal>&gt;=</> cases, the row elements are compared left-to-right,
11093    stopping as soon as an unequal or null pair of elements is found.
11094    If either of this pair of elements is null, the result of the
11095    row comparison is unknown (null); otherwise comparison of this pair
11096    of elements determines the result.  For example,
11097    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
11098    yields true, not null, because the third pair of elements are not
11099    considered.
11100   </para>
11101
11102   <note>
11103    <para>
11104     Prior to <productname>PostgreSQL</productname> 8.2, the
11105     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
11106     cases were not handled per SQL specification.  A comparison like
11107     <literal>ROW(a,b) &lt; ROW(c,d)</>
11108     was implemented as
11109     <literal>a &lt; c AND b &lt; d</>
11110     whereas the correct behavior is equivalent to
11111     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
11112    </para>
11113   </note>
11114
11115 <synopsis>
11116 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
11117 </synopsis>
11118
11119   <para>
11120    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
11121    but it does not yield null for null inputs.  Instead, any null value is
11122    considered unequal to (distinct from) any non-null value, and any two
11123    nulls are considered equal (not distinct).  Thus the result will
11124    either be true or false, never null.
11125   </para>
11126
11127 <synopsis>
11128 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
11129 </synopsis>
11130
11131   <para>
11132    This construct is similar to a <literal>=</literal> row comparison,
11133    but it does not yield null for null inputs.  Instead, any null value is
11134    considered unequal to (distinct from) any non-null value, and any two
11135    nulls are considered equal (not distinct).  Thus the result will always
11136    be either true or false, never null.
11137   </para>
11138
11139   <note>
11140    <para>
11141     The SQL specification requires row-wise comparison to return NULL if the
11142     result depends on comparing two NULL values or a NULL and a non-NULL.
11143     <productname>PostgreSQL</productname> does this only when comparing the
11144     results of two row constructors or comparing a row constructor to the
11145     output of a subquery (as in <xref linkend="functions-subquery">).
11146     In other contexts where two composite-type values are compared, two
11147     NULL field values are considered equal, and a NULL is considered larger
11148     than a non-NULL.  This is necessary in order to have consistent sorting
11149     and indexing behavior for composite types.
11150    </para>
11151   </note>
11152
11153   </sect2>
11154  </sect1>
11155
11156  <sect1 id="functions-srf">
11157   <title>Set Returning Functions</title>
11158
11159   <indexterm zone="functions-srf">
11160    <primary>set returning functions</primary>
11161    <secondary>functions</secondary>
11162   </indexterm>
11163
11164   <indexterm>
11165    <primary>generate_series</primary>
11166   </indexterm>
11167
11168   <para>
11169    This section describes functions that possibly return more than one row.
11170    Currently the only functions in this class are series generating functions,
11171    as detailed in <xref linkend="functions-srf-series"> and
11172    <xref linkend="functions-srf-subscripts">.
11173   </para>
11174
11175   <table id="functions-srf-series">
11176    <title>Series Generating Functions</title>
11177    <tgroup cols="4">
11178     <thead>
11179      <row>
11180       <entry>Function</entry>
11181       <entry>Argument Type</entry>
11182       <entry>Return Type</entry>
11183       <entry>Description</entry>
11184      </row>
11185     </thead>
11186
11187     <tbody>
11188      <row>
11189       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>)</literal></entry>
11190       <entry><type>int</type> or <type>bigint</type></entry>
11191       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
11192       <entry>
11193        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11194        with a step size of one
11195       </entry>
11196      </row>
11197
11198      <row>
11199       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</literal></entry>
11200       <entry><type>int</type> or <type>bigint</type></entry>
11201       <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
11202       <entry>
11203        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11204        with a step size of <parameter>step</parameter>
11205       </entry>
11206      </row>
11207
11208      <row>
11209       <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</literal></entry>
11210       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
11211       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
11212       <entry>
11213        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11214        with a step size of <parameter>step</parameter>
11215       </entry>
11216      </row>
11217
11218     </tbody>
11219    </tgroup>
11220   </table>
11221
11222   <para>
11223    When <parameter>step</parameter> is positive, zero rows are returned if
11224    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
11225    Conversely, when <parameter>step</parameter> is negative, zero rows are
11226    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
11227    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
11228    for <parameter>step</parameter> to be zero. Some examples follow:
11229 <programlisting>
11230 SELECT * FROM generate_series(2,4);
11231  generate_series
11232 -----------------
11233                2
11234                3
11235                4
11236 (3 rows)
11237
11238 SELECT * FROM generate_series(5,1,-2);
11239  generate_series
11240 -----------------
11241                5
11242                3
11243                1
11244 (3 rows)
11245
11246 SELECT * FROM generate_series(4,3);
11247  generate_series
11248 -----------------
11249 (0 rows)
11250
11251 -- this example relies on the date-plus-integer operator
11252 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
11253    dates
11254 ------------
11255  2004-02-05
11256  2004-02-12
11257  2004-02-19
11258 (3 rows)
11259
11260 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
11261                               '2008-03-04 12:00', '10 hours');
11262    generate_series   
11263 ---------------------
11264  2008-03-01 00:00:00
11265  2008-03-01 10:00:00
11266  2008-03-01 20:00:00
11267  2008-03-02 06:00:00
11268  2008-03-02 16:00:00
11269  2008-03-03 02:00:00
11270  2008-03-03 12:00:00
11271  2008-03-03 22:00:00
11272  2008-03-04 08:00:00
11273 (9 rows)
11274 </programlisting>
11275   </para>
11276
11277   <table id="functions-srf-subscripts">
11278    <title>Subscript Generating Functions</title>
11279    <tgroup cols="3">
11280     <thead>
11281      <row>
11282       <entry>Function</entry>
11283       <entry>Return Type</entry>
11284       <entry>Description</entry>
11285      </row>
11286     </thead>
11287
11288     <tbody>
11289      <row>
11290       <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</literal></entry>
11291       <entry><type>setof int</type></entry>
11292       <entry>
11293        Generate a series comprising the given array's subscripts.
11294       </entry>
11295      </row>
11296
11297      <row>
11298       <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</literal></entry>
11299       <entry><type>setof int</type></entry>
11300       <entry>
11301        Generate a series comprising the given array's subscripts. When
11302        <parameter>reverse</parameter> is true, the series is returned in
11303        reverse order.
11304       </entry>
11305      </row>
11306
11307     </tbody>
11308    </tgroup>
11309   </table>
11310
11311   <indexterm>
11312    <primary>generate_subscripts</primary>
11313   </indexterm>
11314
11315   <para>
11316    <function>generate_subscripts</> is a convenience function that generates
11317    the set of valid subscripts for the specified dimension of the given
11318    array.
11319    Zero rows are returned for arrays that do not have the requested dimension,
11320    or for NULL arrays (but valid subscripts are returned for NULL array
11321    elements).  Some examples follow:
11322 <programlisting>
11323 -- basic usage
11324 select generate_subscripts('{NULL,1,NULL,2}'::int[], 1) as s;
11325  s 
11326 ---
11327  1
11328  2
11329  3
11330  4
11331 (4 rows)
11332
11333 -- presenting an array, the subscript and the subscripted
11334 -- value requires a subquery
11335 select * from arrays;
11336          a          
11337 --------------------
11338  {-1,-2}
11339  {100,200}
11340 (2 rows)
11341
11342 select a as array, s as subscript, a[s] as value
11343 from (select generate_subscripts(a, 1) as s, a from arrays) foo;
11344    array   | subscript | value 
11345 -----------+-----------+-------
11346  {-1,-2}   |         1 |    -1
11347  {-1,-2}   |         2 |    -2
11348  {100,200} |         1 |   100
11349  {100,200} |         2 |   200
11350 (4 rows)
11351
11352 -- unnest a 2D array
11353 create or replace function unnest2(anyarray)
11354 returns setof anyelement as $$
11355 select $1[i][j] 
11356    from generate_subscripts($1,1) g1(i),
11357         generate_subscripts($1,2) g2(j);
11358 $$ language sql immutable;
11359 CREATE FUNCTION
11360 postgres=# select * from unnest2(array[[1,2],[3,4]]);
11361  unnest2 
11362 ---------
11363        1
11364        2
11365        3
11366        4
11367 (4 rows)
11368 </programlisting>
11369   </para>
11370
11371  </sect1>
11372
11373  <sect1 id="functions-info">
11374   <title>System Information Functions</title>
11375
11376   <para>
11377    <xref linkend="functions-info-session-table"> shows several
11378    functions that extract session and system information.
11379   </para>
11380
11381   <para>
11382    In addition to the functions listed in this section, there are a number of
11383    functions related to the statistics system that also provide system
11384    information. See <xref linkend="monitoring-stats-views"> for more
11385    information.
11386   </para>
11387
11388    <table id="functions-info-session-table">
11389     <title>Session Information Functions</title>
11390     <tgroup cols="3">
11391      <thead>
11392       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11393      </thead>
11394
11395      <tbody>
11396       <row>
11397        <entry><literal><function>current_catalog</function></literal></entry>
11398        <entry><type>name</type></entry>
11399        <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
11400       </row>
11401
11402       <row>
11403        <entry><literal><function>current_database</function>()</literal></entry>
11404        <entry><type>name</type></entry>
11405        <entry>name of current database</entry>
11406       </row>
11407
11408       <row>
11409        <entry><literal><function>current_schema</function>[()]</literal></entry>
11410        <entry><type>name</type></entry>
11411        <entry>name of current schema</entry>
11412       </row>
11413
11414       <row>
11415        <entry><literal><function>current_schemas</function>(<type>boolean</type>)</literal></entry>
11416        <entry><type>name[]</type></entry>
11417        <entry>names of schemas in search path optionally including implicit schemas</entry>
11418       </row>
11419
11420       <row>
11421        <entry><literal><function>current_user</function></literal></entry>
11422        <entry><type>name</type></entry>
11423        <entry>user name of current execution context</entry>
11424       </row>
11425
11426       <row>
11427        <entry><literal><function>current_query</function></literal></entry>
11428        <entry><type>text</type></entry>
11429        <entry>text of the currently executing query, as submitted
11430        by the client (might contain more than one statement)</entry>
11431       </row>  
11432
11433       <row>
11434        <!-- See also the entry for this in monitoring.sgml -->
11435        <entry><literal><function>pg_backend_pid</function>()</literal></entry>
11436        <entry><type>int</type></entry>
11437        <entry>
11438         Process ID of the server process attached to the current session
11439        </entry>
11440       </row>
11441
11442       <row>
11443        <entry><literal><function>inet_client_addr</function>()</literal></entry>
11444        <entry><type>inet</type></entry>
11445        <entry>address of the remote connection</entry>
11446       </row>
11447
11448       <row>
11449        <entry><literal><function>inet_client_port</function>()</literal></entry>
11450        <entry><type>int</type></entry>
11451        <entry>port of the remote connection</entry>
11452       </row>
11453
11454       <row>
11455        <entry><literal><function>inet_server_addr</function>()</literal></entry>
11456        <entry><type>inet</type></entry>
11457        <entry>address of the local connection</entry>
11458       </row>
11459
11460       <row>
11461        <entry><literal><function>inet_server_port</function>()</literal></entry>
11462        <entry><type>int</type></entry>
11463        <entry>port of the local connection</entry>
11464       </row>
11465
11466       <row>
11467        <entry><literal><function>pg_my_temp_schema</function>()</literal></entry>
11468        <entry><type>oid</type></entry>
11469        <entry>OID of session's temporary schema, or 0 if none</entry>
11470       </row>
11471
11472       <row>
11473        <entry><literal><function>pg_is_other_temp_schema</function>(<type>oid</type>)</literal></entry>
11474        <entry><type>boolean</type></entry>
11475        <entry>is schema another session's temporary schema?</entry>
11476       </row>
11477
11478       <row>
11479        <entry><literal><function>pg_postmaster_start_time</function>()</literal></entry>
11480        <entry><type>timestamp with time zone</type></entry>
11481        <entry>server start time</entry>
11482       </row>
11483
11484       <row>
11485        <entry><literal><function>pg_conf_load_time</function>()</literal></entry>
11486        <entry><type>timestamp with time zone</type></entry>
11487        <entry>configuration load time</entry>
11488       </row>
11489
11490       <row>
11491        <entry><literal><function>session_user</function></literal></entry>
11492        <entry><type>name</type></entry>
11493        <entry>session user name</entry>
11494       </row>
11495
11496       <row>
11497        <entry><literal><function>user</function></literal></entry>
11498        <entry><type>name</type></entry>
11499        <entry>equivalent to <function>current_user</function></entry>
11500       </row>
11501
11502       <row>
11503        <entry><literal><function>version</function>()</literal></entry>
11504        <entry><type>text</type></entry>
11505        <entry><productname>PostgreSQL</> version information</entry>
11506       </row>
11507      </tbody>
11508     </tgroup>
11509    </table>
11510
11511    <indexterm>
11512     <primary>user</primary>
11513     <secondary>current</secondary>
11514    </indexterm>
11515
11516    <indexterm>
11517     <primary>schema</primary>
11518     <secondary>current</secondary>
11519    </indexterm>
11520
11521    <indexterm>
11522     <primary>search path</primary>
11523     <secondary>current</secondary>
11524    </indexterm>
11525
11526    <indexterm>
11527     <primary>current_catalog</primary>
11528    </indexterm>
11529
11530    <indexterm>
11531     <primary>current_database</primary>
11532    </indexterm>
11533
11534    <indexterm>
11535     <primary>current_schema</primary>
11536    </indexterm>
11537
11538    <indexterm>
11539     <primary>current_user</primary>
11540    </indexterm>
11541
11542    <para>
11543     The <function>session_user</function> is normally the user who initiated
11544     the current database connection; but superusers can change this setting
11545     with <xref linkend="sql-set-session-authorization" endterm="sql-set-session-authorization-title">.
11546     The <function>current_user</function> is the user identifier
11547     that is applicable for permission checking. Normally it is equal
11548     to the session user, but it can be changed with
11549     <xref linkend="sql-set-role" endterm="sql-set-role-title">.
11550     It also changes during the execution of
11551     functions with the attribute <literal>SECURITY DEFINER</literal>.
11552     In Unix parlance, the session user is the <quote>real user</quote> and
11553     the current user is the <quote>effective user</quote>.
11554    </para>
11555
11556    <note>
11557     <para>
11558      <function>current_catalog</function>, <function>current_schema</function>,
11559      <function>current_user</function>, <function>session_user</function>,
11560      and <function>user</function> have special syntactic status
11561      in <acronym>SQL</acronym>: they must be called without trailing
11562      parentheses (optional in PostgreSQL in the case
11563      of <function>current_schema</function>).
11564     </para>
11565    </note>
11566
11567    <para>
11568     <function>current_schema</function> returns the name of the schema that is
11569     first in the search path (or a null value if the search path is
11570     empty).  This is the schema that will be used for any tables or
11571     other named objects that are created without specifying a target schema.
11572     <function>current_schemas(boolean)</function> returns an array of the names of all
11573     schemas presently in the search path.  The Boolean option determines whether or not
11574     implicitly included system schemas such as <literal>pg_catalog</> are included in the
11575     returned search path.
11576    </para>
11577
11578    <note>
11579     <para>
11580      The search path can be altered at run time.  The command is:
11581 <programlisting>
11582 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
11583 </programlisting>
11584     </para>
11585    </note>
11586
11587    <indexterm>
11588     <primary>inet_client_addr</primary>
11589    </indexterm>
11590
11591    <indexterm>
11592     <primary>inet_client_port</primary>
11593    </indexterm>
11594
11595    <indexterm>
11596     <primary>inet_server_addr</primary>
11597    </indexterm>
11598
11599    <indexterm>
11600     <primary>inet_server_port</primary>
11601    </indexterm>
11602
11603    <para>
11604      <function>inet_client_addr</function> returns the IP address of the
11605      current client, and <function>inet_client_port</function> returns the
11606      port number.
11607      <function>inet_server_addr</function> returns the IP address on which
11608      the server accepted the current connection, and
11609      <function>inet_server_port</function> returns the port number.
11610      All these functions return NULL if the current connection is via a
11611      Unix-domain socket.
11612    </para>
11613
11614    <indexterm>
11615     <primary>pg_my_temp_schema</primary>
11616    </indexterm>
11617
11618    <indexterm>
11619     <primary>pg_is_other_temp_schema</primary>
11620    </indexterm>
11621
11622    <para>
11623     <function>pg_my_temp_schema</function> returns the OID of the current
11624     session's temporary schema, or zero if it has none (because it has not
11625     created any temporary tables).
11626     <function>pg_is_other_temp_schema</function> returns true if the
11627     given OID is the OID of another session's temporary schema.
11628     (This can be useful, for example, to exclude other sessions' temporary
11629     tables from a catalog display.)
11630    </para>
11631
11632    <indexterm>
11633     <primary>pg_postmaster_start_time</primary>
11634    </indexterm>
11635
11636    <para>
11637     <function>pg_postmaster_start_time</function> returns the
11638     <type>timestamp with time zone</type> when the
11639     server started.
11640    </para>
11641
11642    <indexterm>
11643     <primary>pg_conf_load_time</primary>
11644    </indexterm>
11645
11646    <para>
11647     <function>pg_conf_load_time</function> returns the
11648     <type>timestamp with time zone</type> when the
11649     server configuration files were last loaded.
11650     (If the current session was alive at the time, this will be the time
11651     when the session itself re-read the configuration files, so the
11652     reading will vary a little in different sessions.  Otherwise it is
11653     the time when the postmaster process re-read the configuration files.)
11654    </para>
11655
11656    <indexterm>
11657     <primary>version</primary>
11658    </indexterm>
11659
11660    <para>
11661     <function>version</function> returns a string describing the
11662     <productname>PostgreSQL</productname> server's version.
11663    </para>
11664
11665   <indexterm>
11666    <primary>privilege</primary>
11667    <secondary>querying</secondary>
11668   </indexterm>
11669
11670   <para>
11671    <xref linkend="functions-info-access-table"> lists functions that
11672    allow the user to query object access privileges programmatically.
11673    See <xref linkend="ddl-priv"> for more information about
11674    privileges.
11675   </para>
11676
11677    <table id="functions-info-access-table">
11678     <title>Access Privilege Inquiry Functions</title>
11679     <tgroup cols="3">
11680      <thead>
11681       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11682      </thead>
11683
11684      <tbody>
11685       <row>
11686        <entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
11687                                   <parameter>table</parameter>,
11688                                   <parameter>privilege</parameter>)</literal>
11689        </entry>
11690        <entry><type>boolean</type></entry>
11691        <entry>does user have privilege for any column of table</entry>
11692       </row>
11693       <row>
11694        <entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
11695                                   <parameter>privilege</parameter>)</literal>
11696        </entry>
11697        <entry><type>boolean</type></entry>
11698        <entry>does current user have privilege for any column of table</entry>
11699       </row>
11700       <row>
11701        <entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
11702                                   <parameter>table</parameter>,
11703                                   <parameter>column</parameter>,
11704                                   <parameter>privilege</parameter>)</literal>
11705        </entry>
11706        <entry><type>boolean</type></entry>
11707        <entry>does user have privilege for column</entry>
11708       </row>
11709       <row>
11710        <entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
11711                                   <parameter>column</parameter>,
11712                                   <parameter>privilege</parameter>)</literal>
11713        </entry>
11714        <entry><type>boolean</type></entry>
11715        <entry>does current user have privilege for column</entry>
11716       </row>
11717       <row>
11718        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
11719                                   <parameter>database</parameter>,
11720                                   <parameter>privilege</parameter>)</literal>
11721        </entry>
11722        <entry><type>boolean</type></entry>
11723        <entry>does user have privilege for database</entry>
11724       </row>
11725       <row>
11726        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
11727                                   <parameter>privilege</parameter>)</literal>
11728        </entry>
11729        <entry><type>boolean</type></entry>
11730        <entry>does current user have privilege for database</entry>
11731       </row>
11732       <row>
11733        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
11734                                   <parameter>fdw</parameter>,
11735                                   <parameter>privilege</parameter>)</literal>
11736        </entry>
11737        <entry><type>boolean</type></entry>
11738        <entry>does user have privilege for foreign-data wrapper</entry>
11739       </row>
11740       <row>
11741        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
11742                                   <parameter>privilege</parameter>)</literal>
11743        </entry>
11744        <entry><type>boolean</type></entry>
11745        <entry>does current user have privilege for foreign-data wrapper</entry>
11746       </row>
11747       <row>
11748        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
11749                                   <parameter>function</parameter>,
11750                                   <parameter>privilege</parameter>)</literal>
11751        </entry>
11752        <entry><type>boolean</type></entry>
11753        <entry>does user have privilege for function</entry>
11754       </row>
11755       <row>
11756        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
11757                                   <parameter>privilege</parameter>)</literal>
11758        </entry>
11759        <entry><type>boolean</type></entry>
11760        <entry>does current user have privilege for function</entry>
11761       </row>
11762       <row>
11763        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
11764                                   <parameter>language</parameter>,
11765                                   <parameter>privilege</parameter>)</literal>
11766        </entry>
11767        <entry><type>boolean</type></entry>
11768        <entry>does user have privilege for language</entry>
11769       </row>
11770       <row>
11771        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
11772                                   <parameter>privilege</parameter>)</literal>
11773        </entry>
11774        <entry><type>boolean</type></entry>
11775        <entry>does current user have privilege for language</entry>
11776       </row>
11777       <row>
11778        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
11779                                   <parameter>schema</parameter>,
11780                                   <parameter>privilege</parameter>)</literal>
11781        </entry>
11782        <entry><type>boolean</type></entry>
11783        <entry>does user have privilege for schema</entry>
11784       </row>
11785       <row>
11786        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
11787                                   <parameter>privilege</parameter>)</literal>
11788        </entry>
11789        <entry><type>boolean</type></entry>
11790        <entry>does current user have privilege for schema</entry>
11791       </row>
11792       <row>
11793        <entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
11794                                   <parameter>server</parameter>,
11795                                   <parameter>privilege</parameter>)</literal>
11796        </entry>
11797        <entry><type>boolean</type></entry>
11798        <entry>does user have privilege for foreign server</entry>
11799       </row>
11800       <row>
11801        <entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
11802                                   <parameter>privilege</parameter>)</literal>
11803        </entry>
11804        <entry><type>boolean</type></entry>
11805        <entry>does current user have privilege for foreign server</entry>
11806       </row>
11807       <row>
11808        <entry><literal><function>has_sequence_privilege</function>(<parameter>user</parameter>,
11809                                   <parameter>sequence</parameter>,
11810                                   <parameter>privilege</parameter>)</literal>
11811        </entry>
11812        <entry><type>boolean</type></entry>
11813        <entry>does user have privilege for sequence</entry>
11814       </row>
11815       <row>
11816        <entry><literal><function>has_sequence_privilege</function>(<parameter>sequence</parameter>,
11817                                   <parameter>privilege</parameter>)</literal>
11818        </entry>
11819        <entry><type>boolean</type></entry>
11820        <entry>does current user have privilege for sequence</entry>
11821       </row>
11822       <row>
11823        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
11824                                   <parameter>table</parameter>,
11825                                   <parameter>privilege</parameter>)</literal>
11826        </entry>
11827        <entry><type>boolean</type></entry>
11828        <entry>does user have privilege for table</entry>
11829       </row>
11830       <row>
11831        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
11832                                   <parameter>privilege</parameter>)</literal>
11833        </entry>
11834        <entry><type>boolean</type></entry>
11835        <entry>does current user have privilege for table</entry>
11836       </row>
11837       <row>
11838        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
11839                                   <parameter>tablespace</parameter>,
11840                                   <parameter>privilege</parameter>)</literal>
11841        </entry>
11842        <entry><type>boolean</type></entry>
11843        <entry>does user have privilege for tablespace</entry>
11844       </row>
11845       <row>
11846        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
11847                                   <parameter>privilege</parameter>)</literal>
11848        </entry>
11849        <entry><type>boolean</type></entry>
11850        <entry>does current user have privilege for tablespace</entry>
11851       </row>
11852       <row>
11853        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
11854                                   <parameter>role</parameter>,
11855                                   <parameter>privilege</parameter>)</literal>
11856        </entry>
11857        <entry><type>boolean</type></entry>
11858        <entry>does user have privilege for role</entry>
11859       </row>
11860       <row>
11861        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
11862                                   <parameter>privilege</parameter>)</literal>
11863        </entry>
11864        <entry><type>boolean</type></entry>
11865        <entry>does current user have privilege for role</entry>
11866       </row>
11867      </tbody>
11868     </tgroup>
11869    </table>
11870
11871    <indexterm>
11872     <primary>has_any_column_privilege</primary>
11873    </indexterm>
11874    <indexterm>
11875     <primary>has_column_privilege</primary>
11876    </indexterm>
11877    <indexterm>
11878     <primary>has_database_privilege</primary>
11879    </indexterm>
11880    <indexterm>
11881     <primary>has_function_privilege</primary>
11882    </indexterm>
11883    <indexterm>
11884     <primary>has_foreign_data_wrapper_privilege</primary>
11885    </indexterm>
11886    <indexterm>
11887     <primary>has_language_privilege</primary>
11888    </indexterm>
11889    <indexterm>
11890     <primary>has_schema_privilege</primary>
11891    </indexterm>
11892    <indexterm>
11893     <primary>has_server_privilege</primary>
11894    </indexterm>
11895    <indexterm>
11896     <primary>has_sequence_privilege</primary>
11897    </indexterm>
11898    <indexterm>
11899     <primary>has_table_privilege</primary>
11900    </indexterm>
11901    <indexterm>
11902     <primary>has_tablespace_privilege</primary>
11903    </indexterm>
11904    <indexterm>
11905     <primary>pg_has_role</primary>
11906    </indexterm>
11907
11908    <para>
11909     <function>has_table_privilege</function> checks whether a user
11910     can access a table in a particular way.  The user can be
11911     specified by name or by OID
11912     (<literal>pg_authid.oid</literal>), or if the argument is
11913     omitted
11914     <function>current_user</function> is assumed.  The table can be specified
11915     by name or by OID.  (Thus, there are actually six variants of
11916     <function>has_table_privilege</function>, which can be distinguished by
11917     the number and types of their arguments.)  When specifying by name,
11918     the name can be schema-qualified if necessary.
11919     The desired access privilege type
11920     is specified by a text string, which must evaluate to one of the
11921     values <literal>SELECT</literal>, <literal>INSERT</literal>,
11922     <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
11923     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.  Optionally,
11924     <literal>WITH GRANT OPTION</> can be added to a privilege type to test
11925     whether the privilege is held with grant option.  Also, multiple privilege
11926     types can be listed separated by commas, in which case the result will
11927     be <literal>true</> if any of the listed privileges is held.
11928     (Case of the privilege string is not significant, and extra whitespace
11929     is allowed between but not within privilege names.)
11930     Some examples:
11931 <programlisting>
11932 SELECT has_table_privilege('myschema.mytable', 'select');
11933 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
11934 </programlisting>
11935    </para>
11936
11937    <para>
11938     <function>has_sequence_privilege</function> checks whether a user
11939     can access a sequence in a particular way.  The possibilities for its
11940     arguments are analogous to <function>has_table_privilege</function>.
11941     The desired access privilege type must evaluate to one of
11942     <literal>USAGE</literal>,
11943     <literal>SELECT</literal>, or
11944     <literal>UPDATE</literal>.
11945    </para>
11946
11947    <para>
11948     <function>has_any_column_privilege</function> checks whether a user can
11949     access any column of a table in a particular way.
11950     Its argument possibilities
11951     are analogous to <function>has_table_privilege</>,
11952     except that the desired access privilege type must evaluate to some
11953     combination of
11954     <literal>SELECT</literal>,
11955     <literal>INSERT</literal>,
11956     <literal>UPDATE</literal>, or
11957     <literal>REFERENCES</literal>.  Note that having any of these privileges
11958     at the table level implicitly grants it for each column of the table,
11959     so <function>has_any_column_privilege</function> will always return
11960     <literal>true</> if <function>has_table_privilege</> does for the same
11961     arguments.  But <function>has_any_column_privilege</> also succeeds if
11962     there is a column-level grant of the privilege for at least one column.
11963    </para>
11964
11965    <para>
11966     <function>has_column_privilege</function> checks whether a user
11967     can access a column in a particular way.
11968     Its argument possibilities
11969     are analogous to <function>has_table_privilege</function>,
11970     with the addition that the column can be specified either by name
11971     or attribute number.
11972     The desired access privilege type must evaluate to some combination of
11973     <literal>SELECT</literal>,
11974     <literal>INSERT</literal>,
11975     <literal>UPDATE</literal>, or
11976     <literal>REFERENCES</literal>.  Note that having any of these privileges
11977     at the table level implicitly grants it for each column of the table.
11978    </para>
11979
11980    <para>
11981     <function>has_database_privilege</function> checks whether a user
11982     can access a database in a particular way.
11983     Its argument possibilities
11984     are analogous to <function>has_table_privilege</function>.
11985     The desired access privilege type must evaluate to some combination of
11986     <literal>CREATE</literal>,
11987     <literal>CONNECT</literal>,
11988     <literal>TEMPORARY</literal>, or
11989     <literal>TEMP</literal> (which is equivalent to
11990     <literal>TEMPORARY</literal>).
11991    </para>
11992
11993    <para>
11994     <function>has_function_privilege</function> checks whether a user
11995     can access a function in a particular way.
11996     Its argument possibilities
11997     are analogous to <function>has_table_privilege</function>.
11998     When specifying a function by a text string rather than by OID,
11999     the allowed input is the same as for the <type>regprocedure</> data type
12000     (see <xref linkend="datatype-oid">).
12001     The desired access privilege type must evaluate to
12002     <literal>EXECUTE</literal>.
12003     An example is:
12004 <programlisting>
12005 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
12006 </programlisting>
12007    </para>
12008
12009    <para>
12010     <function>has_foreign_data_wrapper_privilege</function> checks whether a user
12011     can access a foreign-data wrapper in a particular way.
12012     Its argument possibilities
12013     are analogous to <function>has_table_privilege</function>.
12014     The desired access privilege type must evaluate to
12015     <literal>USAGE</literal>.
12016    </para>
12017
12018    <para>
12019     <function>has_language_privilege</function> checks whether a user
12020     can access a procedural language in a particular way.
12021     Its argument possibilities
12022     are analogous to <function>has_table_privilege</function>.
12023     The desired access privilege type must evaluate to
12024     <literal>USAGE</literal>.
12025    </para>
12026
12027    <para>
12028     <function>has_schema_privilege</function> checks whether a user
12029     can access a schema in a particular way.
12030     Its argument possibilities
12031     are analogous to <function>has_table_privilege</function>.
12032     The desired access privilege type must evaluate to some combination of
12033     <literal>CREATE</literal> or
12034     <literal>USAGE</literal>.
12035    </para>
12036
12037    <para>
12038     <function>has_server_privilege</function> checks whether a user
12039     can access a foreign server in a particular way.
12040     Its argument possibilities
12041     are analogous to <function>has_table_privilege</function>.
12042     The desired access privilege type must evaluate to
12043     <literal>USAGE</literal>.
12044    </para>
12045
12046    <para>
12047     <function>has_tablespace_privilege</function> checks whether a user
12048     can access a tablespace in a particular way.
12049     Its argument possibilities
12050     are analogous to <function>has_table_privilege</function>.
12051     The desired access privilege type must evaluate to
12052     <literal>CREATE</literal>.
12053    </para>
12054
12055    <para>
12056     <function>pg_has_role</function> checks whether a user
12057     can access a role in a particular way.
12058     Its argument possibilities
12059     are analogous to <function>has_table_privilege</function>.
12060     The desired access privilege type must evaluate to some combination of
12061     <literal>MEMBER</literal> or
12062     <literal>USAGE</literal>.
12063     <literal>MEMBER</literal> denotes direct or indirect membership in
12064     the role (that is, the right to do <command>SET ROLE</>), while
12065     <literal>USAGE</literal> denotes whether the privileges of the role
12066     are immediately available without doing <command>SET ROLE</>.
12067    </para>
12068
12069   <para>
12070    <xref linkend="functions-info-schema-table"> shows functions that
12071    determine whether a certain object is <firstterm>visible</> in the
12072    current schema search path.
12073    For example, a table is said to be visible if its
12074    containing schema is in the search path and no table of the same
12075    name appears earlier in the search path.  This is equivalent to the
12076    statement that the table can be referenced by name without explicit
12077    schema qualification.  To list the names of all visible tables:
12078 <programlisting>
12079 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
12080 </programlisting>
12081   </para>
12082
12083    <table id="functions-info-schema-table">
12084     <title>Schema Visibility Inquiry Functions</title>
12085     <tgroup cols="3">
12086      <thead>
12087       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12088      </thead>
12089
12090      <tbody>
12091       <row>
12092        <entry><literal><function>pg_conversion_is_visible</function>(<parameter>conversion_oid</parameter>)</literal>
12093        </entry>
12094        <entry><type>boolean</type></entry>
12095        <entry>is conversion visible in search path</entry>
12096       </row>
12097       <row>
12098        <entry><literal><function>pg_function_is_visible</function>(<parameter>function_oid</parameter>)</literal>
12099        </entry>
12100        <entry><type>boolean</type></entry>
12101        <entry>is function visible in search path</entry>
12102       </row>
12103       <row>
12104        <entry><literal><function>pg_operator_is_visible</function>(<parameter>operator_oid</parameter>)</literal>
12105        </entry>
12106        <entry><type>boolean</type></entry>
12107        <entry>is operator visible in search path</entry>
12108       </row>
12109       <row>
12110        <entry><literal><function>pg_opclass_is_visible</function>(<parameter>opclass_oid</parameter>)</literal>
12111        </entry>
12112        <entry><type>boolean</type></entry>
12113        <entry>is operator class visible in search path</entry>
12114       </row>
12115       <row>
12116        <entry><literal><function>pg_table_is_visible</function>(<parameter>table_oid</parameter>)</literal>
12117        </entry>
12118        <entry><type>boolean</type></entry>
12119        <entry>is table visible in search path</entry>
12120       </row>
12121       <row>
12122        <entry><literal><function>pg_ts_config_is_visible</function>(<parameter>config_oid</parameter>)</literal>
12123        </entry>
12124        <entry><type>boolean</type></entry>
12125        <entry>is text search configuration visible in search path</entry>
12126       </row>
12127       <row>
12128        <entry><literal><function>pg_ts_dict_is_visible</function>(<parameter>dict_oid</parameter>)</literal>
12129        </entry>
12130        <entry><type>boolean</type></entry>
12131        <entry>is text search dictionary visible in search path</entry>
12132       </row>
12133       <row>
12134        <entry><literal><function>pg_ts_parser_is_visible</function>(<parameter>parser_oid</parameter>)</literal>
12135        </entry>
12136        <entry><type>boolean</type></entry>
12137        <entry>is text search parser visible in search path</entry>
12138       </row>
12139       <row>
12140        <entry><literal><function>pg_ts_template_is_visible</function>(<parameter>template_oid</parameter>)</literal>
12141        </entry>
12142        <entry><type>boolean</type></entry>
12143        <entry>is text search template visible in search path</entry>
12144       </row>
12145       <row>
12146        <entry><literal><function>pg_type_is_visible</function>(<parameter>type_oid</parameter>)</literal>
12147        </entry>
12148        <entry><type>boolean</type></entry>
12149        <entry>is type (or domain) visible in search path</entry>
12150       </row>
12151      </tbody>
12152     </tgroup>
12153    </table>
12154
12155    <indexterm>
12156     <primary>pg_conversion_is_visible</primary>
12157    </indexterm>
12158    <indexterm>
12159     <primary>pg_function_is_visible</primary>
12160    </indexterm>
12161    <indexterm>
12162     <primary>pg_operator_is_visible</primary>
12163    </indexterm>
12164    <indexterm>
12165     <primary>pg_opclass_is_visible</primary>
12166    </indexterm>
12167    <indexterm>
12168     <primary>pg_table_is_visible</primary>
12169    </indexterm>
12170    <indexterm>
12171     <primary>pg_ts_config_is_visible</primary>
12172    </indexterm>
12173    <indexterm>
12174     <primary>pg_ts_dict_is_visible</primary>
12175    </indexterm>
12176    <indexterm>
12177     <primary>pg_ts_parser_is_visible</primary>
12178    </indexterm>
12179    <indexterm>
12180     <primary>pg_ts_template_is_visible</primary>
12181    </indexterm>
12182    <indexterm>
12183     <primary>pg_type_is_visible</primary>
12184    </indexterm>
12185
12186    <para>
12187     Each function performs the visibility check for one type of database
12188     object.  Note that <function>pg_table_is_visible</function> can also be used
12189     with views, indexes and sequences; <function>pg_type_is_visible</function>
12190     can also be used with domains. For functions and operators, an object in
12191     the search path is visible if there is no object of the same name
12192     <emphasis>and argument data type(s)</> earlier in the path.  For operator
12193     classes, both name and associated index access method are considered.
12194    </para>
12195
12196    <para>
12197     All these functions require object OIDs to identify the object to be
12198     checked.  If you want to test an object by name, it is convenient to use
12199     the OID alias types (<type>regclass</>, <type>regtype</>,
12200     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
12201     or <type>regdictionary</>),
12202     for example:
12203 <programlisting>
12204 SELECT pg_type_is_visible('myschema.widget'::regtype);
12205 </programlisting>
12206     Note that it would not make much sense to test a non-schema-qualified
12207     type name in this way &mdash; if the name can be recognized at all, it must be visible.
12208    </para>
12209
12210    <indexterm>
12211     <primary>format_type</primary>
12212    </indexterm>
12213
12214    <indexterm>
12215     <primary>pg_get_keywords</primary>
12216    </indexterm>
12217
12218    <indexterm>
12219     <primary>pg_get_viewdef</primary>
12220    </indexterm>
12221
12222    <indexterm>
12223     <primary>pg_get_ruledef</primary>
12224    </indexterm>
12225
12226    <indexterm>
12227     <primary>pg_get_functiondef</primary>
12228    </indexterm>
12229
12230    <indexterm>
12231     <primary>pg_get_function_arguments</primary>
12232    </indexterm>
12233
12234    <indexterm>
12235     <primary>pg_get_function_identity_arguments</primary>
12236    </indexterm>
12237
12238    <indexterm>
12239     <primary>pg_get_function_result</primary>
12240    </indexterm>
12241
12242    <indexterm>
12243     <primary>pg_get_indexdef</primary>
12244    </indexterm>
12245
12246    <indexterm>
12247     <primary>pg_get_triggerdef</primary>
12248    </indexterm>
12249
12250    <indexterm>
12251     <primary>pg_get_constraintdef</primary>
12252    </indexterm>
12253
12254    <indexterm>
12255     <primary>pg_get_expr</primary>
12256    </indexterm>
12257
12258    <indexterm>
12259     <primary>pg_get_userbyid</primary>
12260    </indexterm>
12261
12262    <indexterm>
12263     <primary>pg_get_serial_sequence</primary>
12264    </indexterm>
12265
12266    <indexterm>
12267     <primary>pg_tablespace_databases</primary>
12268    </indexterm>
12269
12270    <indexterm>
12271     <primary>pg_typeof</primary>
12272    </indexterm>
12273
12274   <para>
12275    <xref linkend="functions-info-catalog-table"> lists functions that
12276    extract information from the system catalogs.
12277   </para>
12278
12279    <table id="functions-info-catalog-table">
12280     <title>System Catalog Information Functions</title>
12281     <tgroup cols="3">
12282      <thead>
12283       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12284      </thead>
12285
12286      <tbody>
12287       <row>
12288        <entry><literal><function>format_type</function>(<parameter>type_oid</parameter>, <parameter>typemod</>)</literal></entry>
12289        <entry><type>text</type></entry>
12290        <entry>get SQL name of a data type</entry>
12291       </row>
12292       <row>
12293        <entry><literal><function>pg_get_keywords</function>()</literal></entry>
12294        <entry><type>setof record</type></entry>
12295        <entry>get list of SQL keywords and their categories</entry>
12296       </row>
12297       <row>
12298        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>)</literal></entry>
12299        <entry><type>text</type></entry>
12300        <entry>get definition of a constraint</entry>
12301       </row>
12302       <row>
12303        <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
12304        <entry><type>text</type></entry>
12305        <entry>get definition of a constraint</entry>
12306       </row>
12307       <row>
12308        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>)</literal></entry>
12309        <entry><type>text</type></entry>
12310        <entry>decompile internal form of an expression, assuming that any Vars
12311        in it refer to the relation indicated by the second parameter</entry>
12312       </row>
12313       <row>
12314        <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</literal></entry>
12315        <entry><type>text</type></entry>
12316        <entry>decompile internal form of an expression, assuming that any Vars
12317        in it refer to the relation indicated by the second parameter</entry>
12318       </row>
12319       <row>
12320        <entry><literal><function>pg_get_functiondef</function>(<parameter>func_oid</parameter>)</literal></entry>
12321        <entry><type>text</type></entry>
12322        <entry>get definition of a function</entry>
12323       </row>
12324       <row>
12325        <entry><literal><function>pg_get_function_arguments</function>(<parameter>func_oid</parameter>)</literal></entry>
12326        <entry><type>text</type></entry>
12327        <entry>get argument list of function's definition (with default values)</entry>
12328       </row>
12329       <row>
12330        <entry><literal><function>pg_get_function_identity_arguments</function>(<parameter>func_oid</parameter>)</literal></entry>
12331        <entry><type>text</type></entry>
12332        <entry>get argument list to identify a function (without default values)</entry>
12333       </row>
12334       <row>
12335        <entry><literal><function>pg_get_function_result</function>(<parameter>func_oid</parameter>)</literal></entry>
12336        <entry><type>text</type></entry>
12337        <entry>get <literal>RETURNS</> clause for function</entry>
12338       </row>
12339       <row>
12340        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
12341        <entry><type>text</type></entry>
12342        <entry>get <command>CREATE INDEX</> command for index</entry>
12343       </row>
12344       <row>
12345        <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</literal></entry>
12346        <entry><type>text</type></entry>
12347        <entry>get <command>CREATE INDEX</> command for index,
12348        or definition of just one index column when
12349        <parameter>column_no</> is not zero</entry>
12350       </row>
12351       <row>
12352        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>)</literal></entry>
12353        <entry><type>text</type></entry>
12354        <entry>get <command>CREATE RULE</> command for rule</entry>
12355       </row>
12356       <row>
12357        <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
12358        <entry><type>text</type></entry>
12359        <entry>get <command>CREATE RULE</> command for rule</entry>
12360       </row>
12361       <row>
12362        <entry><literal><function>pg_get_serial_sequence</function>(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</literal></entry>
12363        <entry><type>text</type></entry>
12364        <entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
12365        uses</entry>
12366       </row>
12367       <row>
12368        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
12369        <entry><type>text</type></entry>
12370        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
12371       </row>
12372       <row>
12373        <entry><literal><function>pg_get_userbyid</function>(<parameter>role_oid</parameter>)</literal></entry>
12374        <entry><type>name</type></entry>
12375        <entry>get role name with given OID</entry>
12376       </row>
12377       <row>
12378        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>)</literal></entry>
12379        <entry><type>text</type></entry>
12380        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
12381       </row>
12382       <row>
12383        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</literal></entry>
12384        <entry><type>text</type></entry>
12385        <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
12386       </row>
12387       <row>
12388        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>)</literal></entry>
12389        <entry><type>text</type></entry>
12390        <entry>get underlying <command>SELECT</command> command for view</entry>
12391       </row>
12392       <row>
12393        <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
12394        <entry><type>text</type></entry>
12395        <entry>get underlying <command>SELECT</command> command for view</entry>
12396       </row>
12397       <row>
12398        <entry><literal><function>pg_tablespace_databases</function>(<parameter>tablespace_oid</parameter>)</literal></entry>
12399        <entry><type>setof oid</type></entry>
12400        <entry>get the set of database OIDs that have objects in the tablespace</entry>
12401       </row>
12402       <row>
12403        <entry><literal><function>pg_typeof</function>(<parameter>any</parameter>)</literal></entry>
12404        <entry><type>regtype</type></entry>
12405        <entry>get the data type of any value</entry>
12406       </row>
12407      </tbody>
12408     </tgroup>
12409    </table>
12410
12411   <para>
12412    <function>format_type</function> returns the SQL name of a data type that
12413    is identified by its type OID and possibly a type modifier.  Pass NULL
12414    for the type modifier if no specific modifier is known.
12415   </para>
12416
12417   <para>
12418    <function>pg_get_keywords</function> returns a set of records describing
12419    the SQL keywords recognized by the server. The <structfield>word</> column
12420    contains the keyword.  The <structfield>catcode</> column contains a
12421    category code: <literal>U</> for unreserved, <literal>C</> for column name,
12422    <literal>T</> for type or function name, or <literal>R</> for reserved.
12423    The <structfield>catdesc</> column contains a possibly-localized string
12424    describing the category.
12425   </para>
12426
12427   <para>
12428    <function>pg_get_constraintdef</function>,
12429    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
12430    and <function>pg_get_triggerdef</function>, respectively reconstruct the
12431    creating command for a constraint, index, rule, or trigger. (Note that this
12432    is a decompiled reconstruction, not the original text of the command.)
12433    <function>pg_get_expr</function> decompiles the internal form of an
12434    individual expression, such as the default value for a column.  It can be
12435    useful when examining the contents of system catalogs.  If the expression
12436    might contain Vars, specify the OID of the relation they refer to as the
12437    second parameter; if no Vars are expected, zero is sufficient.
12438    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
12439    query that defines a view. Most of these functions come in two variants,
12440    one of which can optionally <quote>pretty-print</> the result.  The
12441    pretty-printed format is more readable, but the default format is more
12442    likely to be interpreted the same way by future versions of
12443    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
12444    purposes.  Passing <literal>false</> for the pretty-print parameter yields
12445    the same result as the variant that does not have the parameter at all.
12446   </para>
12447
12448   <para>
12449    <function>pg_get_functiondef</> returns a complete
12450    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
12451    <function>pg_get_function_arguments</function> returns the argument list
12452    of a function, in the form it would need to appear in within
12453    <command>CREATE FUNCTION</>.
12454    <function>pg_get_function_result</function> similarly returns the
12455    appropriate <literal>RETURNS</> clause for the function.
12456    <function>pg_get_function_identity_arguments</function> returns the
12457    argument list necessary to identify a function, in the form it
12458    would need to appear in within <command>ALTER FUNCTION</>, for
12459    instance.  This form omits default values.
12460   </para>
12461
12462   <para>
12463    <function>pg_get_serial_sequence</function> returns the name of the
12464    sequence associated with a column, or NULL if no sequence is associated
12465    with the column.  The first input parameter is a table name with
12466    optional schema, and the second parameter is a column name.  Because
12467    the first parameter is potentially a schema and table, it is not treated
12468    as a double-quoted identifier, meaning it is lowercased by default,
12469    while the second parameter, being just a column name, is treated as
12470    double-quoted and has its case preserved.  The function returns a value
12471    suitably formatted for passing to sequence functions (see <xref
12472    linkend="functions-sequence">).  This association can be modified or
12473    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
12474    probably should have been called
12475    <function>pg_get_owned_sequence</function>; its current name reflects the fact
12476    that it's typically used with <type>serial</> or <type>bigserial</>
12477    columns.)
12478   </para>
12479
12480   <para>
12481    <function>pg_get_userbyid</function> extracts a role's name given
12482    its OID.
12483   </para>
12484
12485   <para>
12486    <function>pg_tablespace_databases</function> allows a tablespace to be
12487    examined. It returns the set of OIDs of databases that have objects stored
12488    in the tablespace. If this function returns any rows, the tablespace is not
12489    empty and cannot be dropped. To display the specific objects populating the
12490    tablespace, you will need to connect to the databases identified by
12491    <function>pg_tablespace_databases</function> and query their
12492    <structname>pg_class</> catalogs.
12493   </para>
12494
12495   <para>
12496    <function>pg_typeof</function> returns the OID of the data type of the
12497    value that is passed to it.  This can be helpful for troubleshooting or
12498    dynamically constructing SQL queries.  The function is declared as
12499    returning <type>regtype</>, which is an OID alias type (see
12500    <xref linkend="datatype-oid">); this means that it is the same as an
12501    OID for comparison purposes but displays as a type name.  For example:
12502 <programlisting>
12503 SELECT pg_typeof(33);
12504
12505  pg_typeof 
12506 -----------
12507  integer
12508 (1 row)
12509
12510 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
12511  typlen 
12512 --------
12513       4
12514 (1 row)
12515 </programlisting>
12516   </para>
12517
12518    <indexterm>
12519     <primary>col_description</primary>
12520    </indexterm>
12521
12522    <indexterm>
12523     <primary>obj_description</primary>
12524    </indexterm>
12525
12526    <indexterm>
12527     <primary>shobj_description</primary>
12528    </indexterm>
12529
12530    <indexterm>
12531     <primary>comment</primary>
12532     <secondary sortas="database objects">about database objects</secondary>
12533    </indexterm>
12534
12535    <para>
12536     The functions shown in <xref linkend="functions-info-comment-table">
12537     extract comments previously stored with the <xref linkend="sql-comment"
12538     endterm="sql-comment-title"> command.  A null value is returned if no
12539     comment could be found for the specified parameters.
12540    </para>
12541
12542    <table id="functions-info-comment-table">
12543     <title>Comment Information Functions</title>
12544     <tgroup cols="3">
12545      <thead>
12546       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12547      </thead>
12548
12549      <tbody>
12550       <row>
12551        <entry><literal><function>col_description</function>(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</literal></entry>
12552        <entry><type>text</type></entry>
12553        <entry>get comment for a table column</entry>
12554       </row>
12555       <row>
12556        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12557        <entry><type>text</type></entry>
12558        <entry>get comment for a database object</entry>
12559       </row>
12560       <row>
12561        <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>)</literal></entry>
12562        <entry><type>text</type></entry>
12563        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
12564       </row>
12565       <row>
12566        <entry><literal><function>shobj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12567        <entry><type>text</type></entry>
12568        <entry>get comment for a shared database object</entry>
12569       </row>
12570      </tbody>
12571     </tgroup>
12572    </table>
12573
12574    <para>
12575     <function>col_description</function> returns the comment for a table column,
12576     which is specified by the OID of its table and its column number.
12577     <function>obj_description</function> cannot be used for table columns since
12578     columns do not have OIDs of their own.
12579    </para>
12580
12581    <para>
12582     The two-parameter form of <function>obj_description</function> returns the
12583     comment for a database object specified by its OID and the name of the
12584     containing system catalog.  For example,
12585     <literal>obj_description(123456,'pg_class')</literal>
12586     would retrieve the comment for the table with OID 123456.
12587     The one-parameter form of <function>obj_description</function> requires only
12588     the object OID.  It is deprecated since there is no guarantee that
12589     OIDs are unique across different system catalogs; therefore, the wrong
12590     comment might be returned.
12591    </para>
12592
12593    <para>
12594     <function>shobj_description</function> is used just like
12595     <function>obj_description</function> except it is used for retrieving
12596     comments on shared objects.  Some system catalogs are global to all
12597     databases within each cluster and their descriptions are stored globally
12598     as well.
12599    </para>
12600
12601    <indexterm>
12602     <primary>txid_current</primary>
12603    </indexterm>
12604
12605    <indexterm>
12606     <primary>txid_current_snapshot</primary>
12607    </indexterm>
12608
12609    <indexterm>
12610     <primary>txid_snapshot_xmin</primary>
12611    </indexterm>
12612
12613    <indexterm>
12614     <primary>txid_snapshot_xmax</primary>
12615    </indexterm>
12616
12617    <indexterm>
12618     <primary>txid_snapshot_xip</primary>
12619    </indexterm>
12620
12621    <indexterm>
12622     <primary>txid_visible_in_snapshot</primary>
12623    </indexterm>
12624
12625    <para>
12626     The functions shown in <xref linkend="functions-txid-snapshot">
12627     provide server transaction information in an exportable form.  The main
12628     use of these functions is to determine which transactions were committed
12629     between two snapshots.
12630    </para>
12631
12632    <table id="functions-txid-snapshot">
12633     <title>Transaction IDs and snapshots</title>
12634     <tgroup cols="3">
12635      <thead>
12636       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12637      </thead>
12638
12639      <tbody>
12640       <row>
12641        <entry><literal><function>txid_current</function>()</literal></entry>
12642        <entry><type>bigint</type></entry>
12643        <entry>get current transaction ID</entry>
12644       </row>
12645       <row>
12646        <entry><literal><function>txid_current_snapshot</function>()</literal></entry>
12647        <entry><type>txid_snapshot</type></entry>
12648        <entry>get current snapshot</entry>
12649       </row>
12650       <row>
12651        <entry><literal><function>txid_snapshot_xmin</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12652        <entry><type>bigint</type></entry>
12653        <entry>get xmin of snapshot</entry>
12654       </row>
12655       <row>
12656        <entry><literal><function>txid_snapshot_xmax</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12657        <entry><type>bigint</type></entry>
12658        <entry>get xmax of snapshot</entry>
12659       </row>
12660       <row>
12661        <entry><literal><function>txid_snapshot_xip</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12662        <entry><type>setof bigint</type></entry>
12663        <entry>get in-progress transaction IDs in snapshot</entry>
12664       </row>
12665       <row>
12666        <entry><literal><function>txid_visible_in_snapshot</function>(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</literal></entry>
12667        <entry><type>boolean</type></entry>
12668        <entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
12669       </row>
12670      </tbody>
12671     </tgroup>
12672    </table>
12673
12674    <para>
12675     The internal transaction ID type (<type>xid</>) is 32 bits wide and
12676     wraps around every 4 billion transactions.  However, these functions
12677     export a 64-bit format that is extended with an <quote>epoch</> counter
12678     so it will not wrap around during the life of an installation.
12679     The data type used by these functions, <type>txid_snapshot</type>,
12680     stores information about transaction ID
12681     visibility at a particular moment in time.  Its components are
12682     described in <xref linkend="functions-txid-snapshot-parts">.
12683    </para>
12684
12685    <table id="functions-txid-snapshot-parts">
12686     <title>Snapshot components</title>
12687     <tgroup cols="2">
12688      <thead>
12689       <row>
12690        <entry>Name</entry>
12691        <entry>Description</entry>
12692       </row>
12693      </thead>
12694
12695      <tbody>
12696
12697       <row>
12698        <entry><type>xmin</type></entry>
12699        <entry>
12700          Earliest transaction ID (txid) that is still active.  All earlier
12701          transactions will either be committed and visible, or rolled
12702          back and dead.
12703        </entry>
12704       </row>
12705
12706       <row>
12707        <entry><type>xmax</type></entry>
12708        <entry>
12709         First as-yet-unassigned txid.  All txids greater than or equal to this
12710         are not yet started as of the time of the snapshot, and thus invisible.
12711        </entry>
12712       </row>
12713
12714       <row>
12715        <entry><type>xip_list</type></entry>
12716        <entry>
12717         Active txids at the time of the snapshot.  The list
12718         includes only those active txids between <literal>xmin</>
12719         and <literal>xmax</>; there might be active txids higher
12720         than <literal>xmax</>.  A txid that is <literal>xmin &lt;= txid &lt;
12721         xmax</literal> and not in this list was already completed
12722         at the time of the snapshot, and thus either visible or
12723         dead according to its commit status.  The list does not
12724         include txids of subtransactions.
12725        </entry>
12726       </row>
12727
12728      </tbody>
12729     </tgroup>
12730    </table>
12731
12732    <para>
12733     <type>txid_snapshot</>'s textual representation is
12734     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
12735     For example <literal>10:20:10,14,15</literal> means
12736     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
12737    </para>
12738   </sect1>
12739
12740   <sect1 id="functions-admin">
12741    <title>System Administration Functions</title>
12742
12743    <para>
12744     <xref linkend="functions-admin-set-table"> shows the functions
12745     available to query and alter run-time configuration parameters.
12746    </para>
12747
12748    <table id="functions-admin-set-table">
12749     <title>Configuration Settings Functions</title>
12750     <tgroup cols="3">
12751      <thead>
12752       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12753      </thead>
12754
12755      <tbody>
12756       <row>
12757        <entry>
12758         <literal><function>current_setting</function>(<parameter>setting_name</parameter>)</literal>
12759        </entry>
12760        <entry><type>text</type></entry>
12761        <entry>get current value of setting</entry>
12762       </row>
12763       <row>
12764        <entry>
12765         <literal><function>set_config(<parameter>setting_name</parameter>,
12766                              <parameter>new_value</parameter>,
12767                              <parameter>is_local</parameter>)</function></literal>
12768        </entry>
12769        <entry><type>text</type></entry>
12770        <entry>set parameter and return new value</entry>
12771       </row>
12772      </tbody>
12773     </tgroup>
12774    </table>
12775
12776    <indexterm>
12777     <primary>SET</primary>
12778    </indexterm>
12779
12780    <indexterm>
12781     <primary>SHOW</primary>
12782    </indexterm>
12783
12784    <indexterm>
12785     <primary>configuration</primary>
12786     <secondary sortas="server">of the server</secondary>
12787     <tertiary>functions</tertiary>
12788    </indexterm>
12789
12790    <para>
12791     The function <function>current_setting</function> yields the
12792     current value of the setting <parameter>setting_name</parameter>.
12793     It corresponds to the <acronym>SQL</acronym> command
12794     <command>SHOW</command>.  An example:
12795 <programlisting>
12796 SELECT current_setting('datestyle');
12797
12798  current_setting
12799 -----------------
12800  ISO, MDY
12801 (1 row)
12802 </programlisting>
12803    </para>
12804
12805    <para>
12806     <function>set_config</function> sets the parameter
12807     <parameter>setting_name</parameter> to
12808     <parameter>new_value</parameter>.  If
12809     <parameter>is_local</parameter> is <literal>true</literal>, the
12810     new value will only apply to the current transaction. If you want
12811     the new value to apply for the current session, use
12812     <literal>false</literal> instead. The function corresponds to the
12813     SQL command <command>SET</command>. An example:
12814 <programlisting>
12815 SELECT set_config('log_statement_stats', 'off', false);
12816
12817  set_config
12818 ------------
12819  off
12820 (1 row)
12821 </programlisting>
12822    </para>
12823
12824    <indexterm>
12825     <primary>pg_cancel_backend</primary>
12826    </indexterm>
12827    <indexterm>
12828     <primary>pg_terminate_backend</primary>
12829    </indexterm>
12830    <indexterm>
12831     <primary>pg_reload_conf</primary>
12832    </indexterm>
12833    <indexterm>
12834     <primary>pg_rotate_logfile</primary>
12835    </indexterm>
12836
12837    <indexterm>
12838     <primary>signal</primary>
12839     <secondary sortas="backend">backend processes</secondary>
12840    </indexterm>
12841
12842    <para>
12843     The functions shown in <xref
12844     linkend="functions-admin-signal-table"> send control signals to
12845     other server processes.  Use of these functions is restricted
12846     to superusers.
12847    </para>
12848
12849    <table id="functions-admin-signal-table">
12850     <title>Server Signalling Functions</title>
12851     <tgroup cols="3">
12852      <thead>
12853       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12854       </row>
12855      </thead>
12856
12857      <tbody>
12858       <row>
12859        <entry>
12860         <literal><function>pg_cancel_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12861         </entry>
12862        <entry><type>boolean</type></entry>
12863        <entry>Cancel a backend's current query</entry>
12864       </row>
12865       <row>
12866        <entry>
12867         <literal><function>pg_terminate_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12868         </entry>
12869        <entry><type>boolean</type></entry>
12870        <entry>Terminate a backend</entry>
12871       </row>
12872       <row>
12873        <entry>
12874         <literal><function>pg_reload_conf</function>()</literal>
12875         </entry>
12876        <entry><type>boolean</type></entry>
12877        <entry>Cause server processes to reload their configuration files</entry>
12878       </row>
12879       <row>
12880        <entry>
12881         <literal><function>pg_rotate_logfile</function>()</literal>
12882         </entry>
12883        <entry><type>boolean</type></entry>
12884        <entry>Rotate server's log file</entry>
12885       </row>
12886      </tbody>
12887     </tgroup>
12888    </table>
12889
12890    <para>
12891     Each of these functions returns <literal>true</literal> if
12892     successful and <literal>false</literal> otherwise.
12893    </para>
12894
12895    <para>
12896     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
12897     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
12898     respectively) to backend processes identified by process ID.
12899     The process ID of an active backend can be found from
12900     the <structfield>procpid</structfield> column of the
12901     <structname>pg_stat_activity</structname> view, or by listing the
12902     <command>postgres</command> processes on the server (using
12903     <application>ps</> on Unix or the <application>Task
12904     Manager</> on <productname>Windows</>).
12905    </para>
12906
12907    <para>
12908     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
12909     to the server, causing configuration files
12910     to be reloaded by all server processes.
12911    </para>
12912
12913    <para>
12914     <function>pg_rotate_logfile</> signals the log-file manager to switch
12915     to a new output file immediately.  This works only when the built-in
12916     log collector is running, since otherwise there is no log-file manager 
12917     subprocess.
12918    </para>
12919
12920    <indexterm>
12921     <primary>pg_start_backup</primary>
12922    </indexterm>
12923    <indexterm>
12924     <primary>pg_stop_backup</primary>
12925    </indexterm>
12926    <indexterm>
12927     <primary>pg_switch_xlog</primary>
12928    </indexterm>
12929    <indexterm>
12930     <primary>pg_current_xlog_location</primary>
12931    </indexterm>
12932    <indexterm>
12933     <primary>pg_current_xlog_insert_location</primary>
12934    </indexterm>
12935    <indexterm>
12936     <primary>pg_xlogfile_name_offset</primary>
12937    </indexterm>
12938    <indexterm>
12939     <primary>pg_xlogfile_name</primary>
12940    </indexterm>
12941    <indexterm>
12942     <primary>backup</primary>
12943    </indexterm>
12944
12945    <para>
12946     The functions shown in <xref
12947     linkend="functions-admin-backup-table"> assist in making on-line backups.
12948     Use of the first three functions is restricted to superusers.
12949    </para>
12950
12951    <table id="functions-admin-backup-table">
12952     <title>Backup Control Functions</title>
12953     <tgroup cols="3">
12954      <thead>
12955       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12956       </row>
12957      </thead>
12958
12959      <tbody>
12960       <row>
12961        <entry>
12962         <literal><function>pg_start_backup</function>(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> </optional>)</literal>
12963         </entry>
12964        <entry><type>text</type></entry>
12965        <entry>Prepare for performing on-line backup</entry>
12966       </row>
12967       <row>
12968        <entry>
12969         <literal><function>pg_stop_backup</function>()</literal>
12970         </entry>
12971        <entry><type>text</type></entry>
12972        <entry>Finish performing on-line backup</entry>
12973       </row>
12974       <row>
12975        <entry>
12976         <literal><function>pg_switch_xlog</function>()</literal>
12977         </entry>
12978        <entry><type>text</type></entry>
12979        <entry>Force switch to a new transaction log file</entry>
12980       </row>
12981       <row>
12982        <entry>
12983         <literal><function>pg_current_xlog_location</function>()</literal>
12984         </entry>
12985        <entry><type>text</type></entry>
12986        <entry>Get current transaction log write location</entry>
12987       </row>
12988       <row>
12989        <entry>
12990         <literal><function>pg_current_xlog_insert_location</function>()</literal>
12991         </entry>
12992        <entry><type>text</type></entry>
12993        <entry>Get current transaction log insert location</entry>
12994       </row>
12995       <row>
12996        <entry>
12997         <literal><function>pg_xlogfile_name_offset</function>(<parameter>location</> <type>text</>)</literal>
12998         </entry>
12999        <entry><type>text</>, <type>integer</></entry>
13000        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
13001       </row>
13002       <row>
13003        <entry>
13004         <literal><function>pg_xlogfile_name</function>(<parameter>location</> <type>text</>)</literal>
13005         </entry>
13006        <entry><type>text</type></entry>
13007        <entry>Convert transaction log location string to file name</entry>
13008       </row>
13009      </tbody>
13010     </tgroup>
13011    </table>
13012
13013    <para>
13014     <function>pg_start_backup</> accepts an
13015     arbitrary user-defined label for the backup.  (Typically this would be
13016     the name under which the backup dump file will be stored.)  The function
13017     writes a backup label file (<filename>backup_label</>) into the
13018     database cluster's data directory, performs a checkpoint,
13019     and then returns the backup's starting transaction log location as text.
13020     The user can ignore this result value, but it is
13021     provided in case it is useful.
13022 <programlisting>
13023 postgres=# select pg_start_backup('label_goes_here');
13024  pg_start_backup
13025 -----------------
13026  0/D4445B8
13027 (1 row)
13028 </programlisting>
13029     There is an optional boolean second parameter.  If <literal>true</>,
13030     it specifies executing <function>pg_start_backup</> as quickly as
13031     possible.  This forces an immediate checkpoint which will cause a
13032     spike in I/O operations, slowing any concurrently executing queries.
13033    </para>
13034
13035    <para>
13036     <function>pg_stop_backup</> removes the label file created by
13037     <function>pg_start_backup</>, and creates a backup history file in
13038     the transaction log archive area.  The history file includes the label given to
13039     <function>pg_start_backup</>, the starting and ending transaction log locations for
13040     the backup, and the starting and ending times of the backup.  The return
13041     value is the backup's ending transaction log location (which again
13042     can be ignored).  After recording the ending location, the current
13043     transaction log insertion
13044     point is automatically advanced to the next transaction log file, so that the
13045     ending transaction log file can be archived immediately to complete the backup.
13046    </para>
13047
13048    <para>
13049     <function>pg_switch_xlog</> moves to the next transaction log file, allowing the
13050     current file to be archived (assuming you are using continuous archiving).
13051     The return value is the ending transaction log location + 1 within the just-completed transaction log file.
13052     If there has been no transaction log activity since the last transaction log switch,
13053     <function>pg_switch_xlog</> does nothing and returns the start location
13054     of the transaction log file currently in use.
13055    </para>
13056
13057    <para>
13058     <function>pg_current_xlog_location</> displays the current transaction log write
13059     location in the same format used by the above functions.  Similarly,
13060     <function>pg_current_xlog_insert_location</> displays the current transaction log
13061     insertion point.  The insertion point is the <quote>logical</> end
13062     of the transaction log
13063     at any instant, while the write location is the end of what has actually
13064     been written out from the server's internal buffers.  The write location
13065     is the end of what can be examined from outside the server, and is usually
13066     what you want if you are interested in archiving partially-complete transaction log
13067     files.  The insertion point is made available primarily for server
13068     debugging purposes.  These are both read-only operations and do not
13069     require superuser permissions.
13070    </para>
13071
13072    <para>
13073     You can use <function>pg_xlogfile_name_offset</> to extract the
13074     corresponding transaction log file name and byte offset from the results of any of the
13075     above functions.  For example:
13076 <programlisting>
13077 postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup());
13078         file_name         | file_offset 
13079 --------------------------+-------------
13080  00000001000000000000000D |     4039624
13081 (1 row)
13082 </programlisting>
13083     Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
13084     When the given transaction log location is exactly at a transaction log file boundary, both
13085     these functions return the name of the preceding transaction log file.
13086     This is usually the desired behavior for managing transaction log archiving
13087     behavior, since the preceding file is the last one that currently
13088     needs to be archived.
13089    </para>
13090
13091    <para>
13092     For details about proper usage of these functions, see
13093     <xref linkend="continuous-archiving">.
13094    </para>
13095
13096    <para>
13097     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
13098     the disk space usage of database objects.
13099    </para>
13100
13101    <indexterm>
13102     <primary>pg_column_size</primary>
13103    </indexterm>
13104    <indexterm>
13105     <primary>pg_database_size</primary>
13106    </indexterm>
13107    <indexterm>
13108     <primary>pg_relation_size</primary>
13109    </indexterm>
13110    <indexterm>
13111     <primary>pg_size_pretty</primary>
13112    </indexterm>
13113    <indexterm>
13114     <primary>pg_tablespace_size</primary>
13115    </indexterm>
13116    <indexterm>
13117     <primary>pg_total_relation_size</primary>
13118    </indexterm>
13119
13120    <table id="functions-admin-dbsize">
13121     <title>Database Object Size Functions</title>
13122     <tgroup cols="3">
13123      <thead>
13124       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13125       </row>
13126      </thead>
13127
13128      <tbody>
13129       <row>
13130        <entry><literal><function>pg_column_size</function>(<type>any</type>)</literal></entry>
13131        <entry><type>int</type></entry>
13132        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
13133       </row>
13134       <row>
13135        <entry>
13136         <literal><function>pg_database_size</function>(<type>oid</type>)</literal>
13137         </entry>
13138        <entry><type>bigint</type></entry>
13139        <entry>Disk space used by the database with the specified OID</entry>
13140       </row>
13141       <row>
13142        <entry>
13143         <literal><function>pg_database_size</function>(<type>name</type>)</literal>
13144         </entry>
13145        <entry><type>bigint</type></entry>
13146        <entry>Disk space used by the database with the specified name</entry>
13147       </row>
13148       <row>
13149        <entry>
13150         <literal><function>pg_relation_size</function>(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</literal>
13151         </entry>
13152        <entry><type>bigint</type></entry>
13153        <entry>
13154         Disk space used by the specified fork (<literal>'main'</literal>,
13155         <literal>'fsm'</literal> or <literal>'vm'</>)
13156         of the table or index with the specified OID or name
13157        </entry>
13158       </row>
13159       <row>
13160        <entry>
13161         <literal><function>pg_relation_size</function>(<parameter>relation</parameter> <type>regclass</type>)</literal>
13162         </entry>
13163        <entry><type>bigint</type></entry>
13164        <entry>
13165         Shorthand for <literal>pg_relation_size(..., 'main')</literal>
13166        </entry>
13167       </row>
13168       <row>
13169        <entry>
13170         <literal><function>pg_size_pretty</function>(<type>bigint</type>)</literal>
13171         </entry>
13172        <entry><type>text</type></entry>
13173        <entry>Converts a size in bytes into a human-readable format with size units</entry>
13174       </row>
13175       <row>
13176        <entry>
13177         <literal><function>pg_tablespace_size</function>(<type>oid</type>)</literal>
13178         </entry>
13179        <entry><type>bigint</type></entry>
13180        <entry>Disk space used by the tablespace with the specified OID</entry>
13181       </row>
13182       <row>
13183        <entry>
13184         <literal><function>pg_tablespace_size</function>(<type>name</type>)</literal>
13185         </entry>
13186        <entry><type>bigint</type></entry>
13187        <entry>Disk space used by the tablespace with the specified name</entry>
13188       </row>
13189       <row>
13190        <entry>
13191         <literal><function>pg_total_relation_size</function>(<type>regclass</type>)</literal>
13192         </entry>
13193        <entry><type>bigint</type></entry>
13194        <entry>
13195         Total disk space used by the table with the specified OID or name,
13196         including indexes and <acronym>TOAST</> data
13197        </entry>
13198       </row>
13199      </tbody>
13200     </tgroup>
13201    </table>
13202
13203    <para>
13204     <function>pg_column_size</> shows the space used to store any individual
13205     data value.
13206    </para>
13207
13208    <para>
13209     <function>pg_database_size</function> and <function>pg_tablespace_size</>
13210     accept the OID or name of a database or tablespace, and return the total
13211     disk space used therein.
13212    </para>
13213
13214    <para>
13215     <function>pg_relation_size</> accepts the OID or name of a table, index or
13216     toast table, and returns the size in bytes. Specifying
13217     <literal>'main'</literal> or leaving out the second argument returns the
13218     size of the main data fork of the relation. Specifying
13219     <literal>'fsm'</literal> returns the size of the
13220     Free Space Map (see <xref linkend="storage-fsm">) associated with the
13221     relation. Specifying <literal>'vm'</literal> returns the size of the
13222     Visibility Map (see <xref linkend="storage-vm">) associated with the
13223     relation.
13224    </para>
13225
13226    <para>
13227     <function>pg_size_pretty</> can be used to format the result of one of
13228     the other functions in a human-readable way, using kB, MB, GB or TB as
13229     appropriate.
13230    </para>
13231
13232    <para>
13233     <function>pg_total_relation_size</> accepts the OID or name of a
13234     table or toast table, and returns the size in bytes of the data
13235     and all associated indexes and toast tables.
13236    </para>
13237
13238    <para>
13239     The functions shown in <xref
13240     linkend="functions-admin-genfile"> provide native access to
13241     files on the machine hosting the server. Only files within the
13242     database cluster directory and the <varname>log_directory</> can be
13243     accessed.  Use a relative path for files in the cluster directory,
13244     and a path matching the <varname>log_directory</> configuration setting
13245     for log files.  Use of these functions is restricted to superusers.
13246    </para>
13247
13248    <table id="functions-admin-genfile">
13249     <title>Generic File Access Functions</title>
13250     <tgroup cols="3">
13251      <thead>
13252       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13253       </row>
13254      </thead>
13255
13256      <tbody>
13257       <row>
13258        <entry>
13259         <literal><function>pg_ls_dir</function>(<parameter>dirname</> <type>text</>)</literal>
13260        </entry>
13261        <entry><type>setof text</type></entry>
13262        <entry>List the contents of a directory</entry>
13263       </row>
13264       <row>
13265        <entry>
13266         <literal><function>pg_read_file</function>(<parameter>filename</> <type>text</>, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>)</literal>
13267        </entry>
13268        <entry><type>text</type></entry>
13269        <entry>Return the contents of a text file</entry>
13270       </row>
13271       <row>
13272        <entry>
13273         <literal><function>pg_stat_file</function>(<parameter>filename</> <type>text</>)</literal>
13274        </entry>
13275        <entry><type>record</type></entry>
13276        <entry>Return information about a file</entry>
13277       </row>
13278      </tbody>
13279     </tgroup>
13280    </table>
13281
13282    <indexterm>
13283     <primary>pg_ls_dir</primary>
13284    </indexterm>
13285    <para>
13286     <function>pg_ls_dir</> returns all the names in the specified
13287     directory, except the special entries <quote><literal>.</></> and
13288     <quote><literal>..</></>.
13289    </para>
13290
13291    <indexterm>
13292     <primary>pg_read_file</primary>
13293    </indexterm>
13294    <para>
13295     <function>pg_read_file</> returns part of a text file, starting
13296     at the given <parameter>offset</>, returning at most <parameter>length</>
13297     bytes (less if the end of file is reached first).  If <parameter>offset</>
13298     is negative, it is relative to the end of the file.
13299    </para>
13300
13301    <indexterm>
13302     <primary>pg_stat_file</primary>
13303    </indexterm>
13304    <para>
13305     <function>pg_stat_file</> returns a record containing the file
13306     size, last accessed time stamp, last modified time stamp,
13307     last file status change time stamp (Unix platforms only),
13308     file creation time stamp (Windows only), and a <type>boolean</type>
13309     indicating if it is a directory.  Typical usages include:
13310 <programlisting>
13311 SELECT * FROM pg_stat_file('filename');
13312 SELECT (pg_stat_file('filename')).modification;
13313 </programlisting>
13314    </para>
13315
13316    <para>
13317     The functions shown in <xref linkend="functions-advisory-locks"> manage
13318     advisory locks.  For details about proper use of these functions, see
13319     <xref linkend="advisory-locks">.
13320    </para>
13321
13322    <table id="functions-advisory-locks">
13323     <title>Advisory Lock Functions</title>
13324     <tgroup cols="3">
13325      <thead>
13326       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13327       </row>
13328      </thead>
13329
13330      <tbody>
13331       <row>
13332        <entry>
13333         <literal><function>pg_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
13334        </entry>
13335        <entry><type>void</type></entry>
13336        <entry>Obtain exclusive advisory lock</entry>
13337       </row>
13338       <row>
13339        <entry>
13340         <literal><function>pg_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13341        </entry>
13342        <entry><type>void</type></entry>
13343        <entry>Obtain exclusive advisory lock</entry>
13344       </row>
13345
13346       <row>
13347        <entry>
13348         <literal><function>pg_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
13349        </entry>
13350        <entry><type>void</type></entry>
13351        <entry>Obtain shared advisory lock</entry>
13352       </row>
13353       <row>
13354        <entry>
13355         <literal><function>pg_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13356        </entry>
13357        <entry><type>void</type></entry>
13358        <entry>Obtain shared advisory lock</entry>
13359       </row>
13360
13361       <row>
13362        <entry>
13363         <literal><function>pg_try_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
13364        </entry>
13365        <entry><type>boolean</type></entry>
13366        <entry>Obtain exclusive advisory lock if available</entry>
13367       </row>
13368       <row>
13369        <entry>
13370         <literal><function>pg_try_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13371        </entry>
13372        <entry><type>boolean</type></entry>
13373        <entry>Obtain exclusive advisory lock if available</entry>
13374       </row>
13375
13376       <row>
13377        <entry>
13378         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
13379        </entry>
13380        <entry><type>boolean</type></entry>
13381        <entry>Obtain shared advisory lock if available</entry>
13382       </row>
13383       <row>
13384        <entry>
13385         <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13386        </entry>
13387        <entry><type>boolean</type></entry>
13388        <entry>Obtain shared advisory lock if available</entry>
13389       </row>
13390
13391       <row>
13392        <entry>
13393         <literal><function>pg_advisory_unlock</function>(<parameter>key</> <type>bigint</>)</literal>
13394        </entry>
13395        <entry><type>boolean</type></entry>
13396        <entry>Release an exclusive advisory lock</entry>
13397       </row>
13398       <row>
13399        <entry>
13400         <literal><function>pg_advisory_unlock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13401        </entry>
13402        <entry><type>boolean</type></entry>
13403        <entry>Release an exclusive advisory lock</entry>
13404       </row>
13405
13406       <row>
13407        <entry>
13408         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
13409        </entry>
13410        <entry><type>boolean</type></entry>
13411        <entry>Release a shared advisory lock</entry>
13412       </row>
13413       <row>
13414        <entry>
13415         <literal><function>pg_advisory_unlock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13416        </entry>
13417        <entry><type>boolean</type></entry>
13418        <entry>Release a shared advisory lock</entry>
13419       </row>
13420
13421       <row>
13422        <entry>
13423         <literal><function>pg_advisory_unlock_all</function>()</literal>
13424        </entry>
13425        <entry><type>void</type></entry>
13426        <entry>Release all advisory locks held by the current session</entry>
13427       </row>
13428
13429      </tbody>
13430     </tgroup>
13431    </table>
13432
13433    <indexterm>
13434     <primary>pg_advisory_lock</primary>
13435    </indexterm>
13436    <para>
13437     <function>pg_advisory_lock</> locks an application-defined resource,
13438     which can be identified either by a single 64-bit key value or two
13439     32-bit key values (note that these two key spaces do not overlap). 
13440     The key type is specified in <literal>pg_locks.objid</>.  If
13441     another session already holds a lock on the same resource, the
13442     function will wait until the resource becomes available.  The lock
13443     is exclusive.  Multiple lock requests stack, so that if the same resource
13444     is locked three times it must be also unlocked three times to be
13445     released for other sessions' use.
13446    </para>
13447
13448    <indexterm>
13449     <primary>pg_advisory_lock_shared</primary>
13450    </indexterm>
13451    <para>
13452     <function>pg_advisory_lock_shared</> works the same as
13453     <function>pg_advisory_lock</>,
13454     except the lock can be shared with other sessions requesting shared locks.
13455     Only would-be exclusive lockers are locked out.
13456    </para>
13457
13458    <indexterm>
13459     <primary>pg_try_advisory_lock</primary>
13460    </indexterm>
13461    <para>
13462     <function>pg_try_advisory_lock</> is similar to
13463     <function>pg_advisory_lock</>, except the function will not wait for the
13464     lock to become available.  It will either obtain the lock immediately and
13465     return <literal>true</>, or return <literal>false</> if the lock cannot be
13466     acquired immediately.
13467    </para>
13468
13469    <indexterm>
13470     <primary>pg_try_advisory_lock_shared</primary>
13471    </indexterm>
13472    <para>
13473     <function>pg_try_advisory_lock_shared</> works the same as
13474     <function>pg_try_advisory_lock</>, except it attempts to acquire
13475     a shared rather than an exclusive lock.
13476    </para>
13477
13478    <indexterm>
13479     <primary>pg_advisory_unlock</primary>
13480    </indexterm>
13481    <para>
13482     <function>pg_advisory_unlock</> will release a previously-acquired
13483     exclusive advisory lock.  It
13484     returns <literal>true</> if the lock is successfully released.
13485     If the lock was not held, it will return <literal>false</>,
13486     and in addition, an SQL warning will be raised by the server.
13487    </para>
13488
13489    <indexterm>
13490     <primary>pg_advisory_unlock_shared</primary>
13491    </indexterm>
13492    <para>
13493     <function>pg_advisory_unlock_shared</> works the same as
13494     <function>pg_advisory_unlock</>,
13495     except it releases a shared advisory lock.
13496    </para>
13497
13498    <indexterm>
13499     <primary>pg_advisory_unlock_all</primary>
13500    </indexterm>
13501    <para>
13502     <function>pg_advisory_unlock_all</> will release all advisory locks
13503     held by the current session.  (This function is implicitly invoked
13504     at session end, even if the client disconnects ungracefully.)
13505    </para>
13506
13507   </sect1>
13508
13509   <sect1 id="functions-trigger">
13510    <title>Trigger Functions</title>
13511
13512    <indexterm>
13513      <primary>suppress_redundant_updates_trigger</primary>
13514    </indexterm>
13515
13516    <para>
13517       Currently <productname>PostgreSQL</> provides one built in trigger
13518       function, <function>suppress_redundant_updates_trigger</>, 
13519       which will prevent any update
13520       that does not actually change the data in the row from taking place, in
13521       contrast to the normal behaviour which always performs the update
13522       regardless of whether or not the data has changed. (This normal behaviour
13523       makes updates run faster, since no checking is required, and is also
13524       useful in certain cases.)
13525     </para>
13526
13527     <para>
13528       Ideally, you should normally avoid running updates that don't actually
13529       change the data in the record. Redundant updates can cost considerable
13530       unnecessary time, especially if there are lots of indexes to alter,
13531       and space in dead rows that will eventually have to be vacuumed.
13532       However, detecting such situations in client code is not
13533       always easy, or even possible, and writing expressions to detect
13534       them can be error-prone. An alternative is to use 
13535       <function>suppress_redundant_updates_trigger</>, which will skip
13536       updates that don't change the data. You should use this with care,
13537       however. The trigger takes a small but non-trivial time for each record, 
13538       so if most of the records affected by an update are actually changed,
13539       use of this trigger will actually make the update run slower.
13540     </para>
13541
13542     <para>
13543       The <function>suppress_redundant_updates_trigger</> function can be 
13544       added to a table like this:
13545 <programlisting>
13546 CREATE TRIGGER z_min_update 
13547 BEFORE UPDATE ON tablename
13548 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
13549 </programlisting>
13550       In most cases, you would want to fire this trigger last for each row.
13551       Bearing in mind that triggers fire in name order, you would then
13552       choose a trigger name that comes after the name of any other trigger
13553       you might have on the table.
13554     </para>
13555     <para>
13556        For more information about creating triggers, see
13557         <xref linkend="SQL-CREATETRIGGER">.
13558     </para>
13559   </sect1>
13560 </chapter>