]> granicus.if.org Git - postgresql/blob - doc/src/sgml/func.sgml
Fix grammar.
[postgresql] / doc / src / sgml / func.sgml
1 <!-- doc/src/sgml/func.sgml -->
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 logic system with true,
86     false, and <literal>null</>, which represents <quote>unknown</quote>.
87     Observe the following truth tables:
88
89     <informaltable>
90      <tgroup cols="4">
91       <thead>
92        <row>
93         <entry><replaceable>a</replaceable></entry>
94         <entry><replaceable>b</replaceable></entry>
95         <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
96         <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
97        </row>
98       </thead>
99
100       <tbody>
101        <row>
102         <entry>TRUE</entry>
103         <entry>TRUE</entry>
104         <entry>TRUE</entry>
105         <entry>TRUE</entry>
106        </row>
107
108        <row>
109         <entry>TRUE</entry>
110         <entry>FALSE</entry>
111         <entry>FALSE</entry>
112         <entry>TRUE</entry>
113        </row>
114
115        <row>
116         <entry>TRUE</entry>
117         <entry>NULL</entry>
118         <entry>NULL</entry>
119         <entry>TRUE</entry>
120        </row>
121
122        <row>
123         <entry>FALSE</entry>
124         <entry>FALSE</entry>
125         <entry>FALSE</entry>
126         <entry>FALSE</entry>
127        </row>
128
129        <row>
130         <entry>FALSE</entry>
131         <entry>NULL</entry>
132         <entry>FALSE</entry>
133         <entry>NULL</entry>
134        </row>
135
136        <row>
137         <entry>NULL</entry>
138         <entry>NULL</entry>
139         <entry>NULL</entry>
140         <entry>NULL</entry>
141        </row>
142       </tbody>
143      </tgroup>
144     </informaltable>
145
146     <informaltable>
147      <tgroup cols="2">
148       <thead>
149        <row>
150         <entry><replaceable>a</replaceable></entry>
151         <entry>NOT <replaceable>a</replaceable></entry>
152        </row>
153       </thead>
154
155       <tbody>
156        <row>
157         <entry>TRUE</entry>
158         <entry>FALSE</entry>
159        </row>
160
161        <row>
162         <entry>FALSE</entry>
163         <entry>TRUE</entry>
164        </row>
165
166        <row>
167         <entry>NULL</entry>
168         <entry>NULL</entry>
169        </row>
170       </tbody>
171      </tgroup>
172     </informaltable>
173    </para>
174
175    <para>
176     The operators <literal>AND</literal> and <literal>OR</literal> are
177     commutative, that is, you can switch the left and right operand
178     without affecting the result.  But see <xref
179     linkend="syntax-express-eval"> for more information about the
180     order of evaluation of subexpressions.
181    </para>
182   </sect1>
183
184   <sect1 id="functions-comparison">
185    <title>Comparison Functions and Operators</title>
186
187    <indexterm zone="functions-comparison">
188     <primary>comparison</primary>
189     <secondary>operators</secondary>
190    </indexterm>
191
192    <para>
193     The usual comparison operators are available, as shown in <xref
194     linkend="functions-comparison-op-table">.
195    </para>
196
197    <table id="functions-comparison-op-table">
198     <title>Comparison Operators</title>
199     <tgroup cols="2">
200      <thead>
201       <row>
202        <entry>Operator</entry>
203        <entry>Description</entry>
204       </row>
205      </thead>
206
207      <tbody>
208       <row>
209        <entry> <literal>&lt;</literal> </entry>
210        <entry>less than</entry>
211       </row>
212
213       <row>
214        <entry> <literal>&gt;</literal> </entry>
215        <entry>greater than</entry>
216       </row>
217
218       <row>
219        <entry> <literal>&lt;=</literal> </entry>
220        <entry>less than or equal to</entry>
221       </row>
222
223       <row>
224        <entry> <literal>&gt;=</literal> </entry>
225        <entry>greater than or equal to</entry>
226       </row>
227
228       <row>
229        <entry> <literal>=</literal> </entry>
230        <entry>equal</entry>
231       </row>
232
233       <row>
234        <entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
235        <entry>not equal</entry>
236       </row>
237      </tbody>
238     </tgroup>
239    </table>
240
241    <note>
242     <para>
243      The <literal>!=</literal> operator is converted to
244      <literal>&lt;&gt;</literal> in the parser stage.  It is not
245      possible to implement <literal>!=</literal> and
246      <literal>&lt;&gt;</literal> operators that do different things.
247     </para>
248    </note>
249
250    <para>
251     Comparison operators are available for all relevant data types.
252     All comparison operators are binary operators that
253     return values of type <type>boolean</type>; expressions like
254     <literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
255     no <literal>&lt;</literal> operator to compare a Boolean value with
256     <literal>3</literal>).
257    </para>
258
259    <para>
260     There are also some comparison predicates, as shown in <xref
261     linkend="functions-comparison-pred-table">.  These behave much like
262     operators, but have special syntax mandated by the SQL standard.
263    </para>
264
265    <table id="functions-comparison-pred-table">
266     <title>Comparison Predicates</title>
267     <tgroup cols="2">
268      <thead>
269       <row>
270        <entry>Predicate</entry>
271        <entry>Description</entry>
272       </row>
273      </thead>
274
275      <tbody>
276       <row>
277        <entry> <replaceable>a</> <literal>BETWEEN</> <replaceable>x</> <literal>AND</> <replaceable>y</> </entry>
278        <entry>between</entry>
279       </row>
280
281       <row>
282        <entry> <replaceable>a</> <literal>NOT BETWEEN</> <replaceable>x</> <literal>AND</> <replaceable>y</> </entry>
283        <entry>not between</entry>
284       </row>
285
286       <row>
287        <entry> <replaceable>a</> <literal>BETWEEN SYMMETRIC</> <replaceable>x</> <literal>AND</> <replaceable>y</> </entry>
288        <entry>between, after sorting the comparison values</entry>
289       </row>
290
291       <row>
292        <entry> <replaceable>a</> <literal>NOT BETWEEN SYMMETRIC</> <replaceable>x</> <literal>AND</> <replaceable>y</> </entry>
293        <entry>not between, after sorting the comparison values</entry>
294       </row>
295
296       <row>
297        <entry> <replaceable>a</> <literal>IS DISTINCT FROM</> <replaceable>b</> </entry>
298        <entry>not equal, treating null like an ordinary value</entry>
299       </row>
300
301       <row>
302        <entry><replaceable>a</> <literal>IS NOT DISTINCT FROM</> <replaceable>b</></entry>
303        <entry>equal, treating null like an ordinary value</entry>
304       </row>
305
306       <row>
307        <entry> <replaceable>expression</> <literal>IS NULL</> </entry>
308        <entry>is null</entry>
309       </row>
310
311       <row>
312        <entry> <replaceable>expression</> <literal>IS NOT NULL</> </entry>
313        <entry>is not null</entry>
314       </row>
315
316       <row>
317        <entry> <replaceable>expression</> <literal>ISNULL</> </entry>
318        <entry>is null (nonstandard syntax)</entry>
319       </row>
320
321       <row>
322        <entry> <replaceable>expression</> <literal>NOTNULL</> </entry>
323        <entry>is not null (nonstandard syntax)</entry>
324       </row>
325
326       <row>
327        <entry> <replaceable>boolean_expression</> <literal>IS TRUE</> </entry>
328        <entry>is true</entry>
329       </row>
330
331       <row>
332        <entry> <replaceable>boolean_expression</> <literal>IS NOT TRUE</> </entry>
333        <entry>is false or unknown</entry>
334       </row>
335
336       <row>
337        <entry> <replaceable>boolean_expression</> <literal>IS FALSE</> </entry>
338        <entry>is false</entry>
339       </row>
340
341       <row>
342        <entry> <replaceable>boolean_expression</> <literal>IS NOT FALSE</> </entry>
343        <entry>is true or unknown</entry>
344       </row>
345
346       <row>
347        <entry> <replaceable>boolean_expression</> <literal>IS UNKNOWN</> </entry>
348        <entry>is unknown</entry>
349       </row>
350
351       <row>
352        <entry> <replaceable>boolean_expression</> <literal>IS NOT UNKNOWN</> </entry>
353        <entry>is true or false</entry>
354       </row>
355      </tbody>
356     </tgroup>
357    </table>
358
359    <para>
360     <indexterm>
361      <primary>BETWEEN</primary>
362     </indexterm>
363     The <token>BETWEEN</token> predicate simplifies range tests:
364 <synopsis>
365 <replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
366 </synopsis>
367     is equivalent to
368 <synopsis>
369 <replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
370 </synopsis>
371     Notice that <token>BETWEEN</token> treats the endpoint values as included
372     in the range.
373     <literal>NOT BETWEEN</literal> does the opposite comparison:
374 <synopsis>
375 <replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
376 </synopsis>
377     is equivalent to
378 <synopsis>
379 <replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
380 </synopsis>
381     <indexterm>
382      <primary>BETWEEN SYMMETRIC</primary>
383     </indexterm>
384     <literal>BETWEEN SYMMETRIC</> is like <literal>BETWEEN</>
385     except there is no requirement that the argument to the left of
386     <literal>AND</> be less than or equal to the argument on the right.
387     If it is not, those two arguments are automatically swapped, so that
388     a nonempty range is always implied.
389    </para>
390
391    <para>
392     <indexterm>
393      <primary>IS DISTINCT FROM</primary>
394     </indexterm>
395     <indexterm>
396      <primary>IS NOT DISTINCT FROM</primary>
397     </indexterm>
398     Ordinary comparison operators yield null (signifying <quote>unknown</>),
399     not true or false, when either input is null.  For example,
400     <literal>7 = NULL</> yields null, as does <literal>7 &lt;&gt; NULL</>.  When
401     this behavior is not suitable, use the
402     <literal>IS <optional> NOT </> DISTINCT FROM</literal> predicates:
403 <synopsis>
404 <replaceable>a</replaceable> IS DISTINCT FROM <replaceable>b</replaceable>
405 <replaceable>a</replaceable> IS NOT DISTINCT FROM <replaceable>b</replaceable>
406 </synopsis>
407     For non-null inputs, <literal>IS DISTINCT FROM</literal> is
408     the same as the <literal>&lt;&gt;</> operator.  However, if both
409     inputs are null it returns false, and if only one input is
410     null it returns true.  Similarly, <literal>IS NOT DISTINCT
411     FROM</literal> is identical to <literal>=</literal> for non-null
412     inputs, but it returns true when both inputs are null, and false when only
413     one input is null. Thus, these predicates effectively act as though null
414     were a normal data value, rather than <quote>unknown</>.
415    </para>
416
417    <para>
418     <indexterm>
419      <primary>IS NULL</primary>
420     </indexterm>
421     <indexterm>
422      <primary>IS NOT NULL</primary>
423     </indexterm>
424     <indexterm>
425      <primary>ISNULL</primary>
426     </indexterm>
427     <indexterm>
428      <primary>NOTNULL</primary>
429     </indexterm>
430     To check whether a value is or is not null, use the predicates:
431 <synopsis>
432 <replaceable>expression</replaceable> IS NULL
433 <replaceable>expression</replaceable> IS NOT NULL
434 </synopsis>
435     or the equivalent, but nonstandard, predicates:
436 <synopsis>
437 <replaceable>expression</replaceable> ISNULL
438 <replaceable>expression</replaceable> NOTNULL
439 </synopsis>
440     <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
441    </para>
442
443    <para>
444     Do <emphasis>not</emphasis> write
445     <literal><replaceable>expression</replaceable> = NULL</literal>
446     because <literal>NULL</> is not <quote>equal to</quote>
447     <literal>NULL</>.  (The null value represents an unknown value,
448     and it is not known whether two unknown values are equal.)
449    </para>
450
451   <tip>
452    <para>
453     Some applications might expect that
454     <literal><replaceable>expression</replaceable> = NULL</literal>
455     returns true if <replaceable>expression</replaceable> evaluates to
456     the null value.  It is highly recommended that these applications
457     be modified to comply with the SQL standard. However, if that
458     cannot be done the <xref linkend="guc-transform-null-equals">
459     configuration variable is available. If it is enabled,
460     <productname>PostgreSQL</productname> will convert <literal>x =
461     NULL</literal> clauses to <literal>x IS NULL</literal>.
462    </para>
463   </tip>
464
465    <para>
466     If the <replaceable>expression</replaceable> is row-valued, then
467     <literal>IS NULL</> is true when the row expression itself is null
468     or when all the row's fields are null, while
469     <literal>IS NOT NULL</> is true when the row expression itself is non-null
470     and all the row's fields are non-null.  Because of this behavior,
471     <literal>IS NULL</> and <literal>IS NOT NULL</> do not always return
472     inverse results for row-valued expressions; in particular, a row-valued
473     expression that contains both null and non-null fields will return false
474     for both tests.  In some cases, it may be preferable to
475     write <replaceable>row</replaceable> <literal>IS DISTINCT FROM NULL</>
476     or <replaceable>row</replaceable> <literal>IS NOT DISTINCT FROM NULL</>,
477     which will simply check whether the overall row value is null without any
478     additional tests on the row fields.
479    </para>
480
481    <para>
482     <indexterm>
483      <primary>IS TRUE</primary>
484     </indexterm>
485     <indexterm>
486      <primary>IS NOT TRUE</primary>
487     </indexterm>
488     <indexterm>
489      <primary>IS FALSE</primary>
490     </indexterm>
491     <indexterm>
492      <primary>IS NOT FALSE</primary>
493     </indexterm>
494     <indexterm>
495      <primary>IS UNKNOWN</primary>
496     </indexterm>
497     <indexterm>
498      <primary>IS NOT UNKNOWN</primary>
499     </indexterm>
500     Boolean values can also be tested using the predicates
501 <synopsis>
502 <replaceable>boolean_expression</replaceable> IS TRUE
503 <replaceable>boolean_expression</replaceable> IS NOT TRUE
504 <replaceable>boolean_expression</replaceable> IS FALSE
505 <replaceable>boolean_expression</replaceable> IS NOT FALSE
506 <replaceable>boolean_expression</replaceable> IS UNKNOWN
507 <replaceable>boolean_expression</replaceable> IS NOT UNKNOWN
508 </synopsis>
509     These will always return true or false, never a null value, even when the
510     operand is null.
511     A null input is treated as the logical value <quote>unknown</>.
512     Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
513     effectively the same as <literal>IS NULL</literal> and
514     <literal>IS NOT NULL</literal>, respectively, except that the input
515     expression must be of Boolean type.
516    </para>
517
518 <!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
519    <para>
520     <indexterm>
521      <primary>IS OF</primary>
522     </indexterm>
523     <indexterm>
524      <primary>IS NOT OF</primary>
525     </indexterm>
526     It is possible to check the data type of an expression using the
527     predicates
528 <synopsis>
529 <replaceable>expression</replaceable> IS OF (typename, ...)
530 <replaceable>expression</replaceable> IS NOT OF (typename, ...)
531 </synopsis>
532     They return a boolean value based on whether the expression's data
533     type is one of the listed data types.
534    </para>
535 -->
536
537    <para>
538     Some comparison-related functions are also available, as shown in <xref
539     linkend="functions-comparison-func-table">.
540    </para>
541
542   <table id="functions-comparison-func-table">
543     <title>Comparison Functions</title>
544     <tgroup cols="4">
545      <thead>
546       <row>
547        <entry>Function</entry>
548        <entry>Description</entry>
549        <entry>Example</entry>
550        <entry>Example Result</entry>
551       </row>
552      </thead>
553      <tbody>
554       <row>
555        <entry>
556          <indexterm>
557           <primary>num_nonnulls</primary>
558          </indexterm>
559          <literal>num_nonnulls(VARIADIC "any")</literal>
560        </entry>
561        <entry>returns the number of non-null arguments</entry>
562        <entry><literal>num_nonnulls(1, NULL, 2)</literal></entry>
563        <entry><literal>2</literal></entry>
564       </row>
565       <row>
566        <entry>
567          <indexterm>
568           <primary>num_nulls</primary>
569          </indexterm>
570          <literal>num_nulls(VARIADIC "any")</literal>
571        </entry>
572        <entry>returns the number of null arguments</entry>
573        <entry><literal>num_nulls(1, NULL, 2)</literal></entry>
574        <entry><literal>1</literal></entry>
575       </row>
576      </tbody>
577     </tgroup>
578    </table>
579
580   </sect1>
581
582   <sect1 id="functions-math">
583    <title>Mathematical Functions and Operators</title>
584
585    <para>
586     Mathematical operators are provided for many
587     <productname>PostgreSQL</productname> types. For types without
588     standard mathematical conventions
589     (e.g., date/time types) we
590     describe the actual behavior in subsequent sections.
591    </para>
592
593    <para>
594     <xref linkend="functions-math-op-table"> shows the available mathematical operators.
595    </para>
596
597    <table id="functions-math-op-table">
598     <title>Mathematical Operators</title>
599
600     <tgroup cols="4">
601      <thead>
602       <row>
603        <entry>Operator</entry>
604        <entry>Description</entry>
605        <entry>Example</entry>
606        <entry>Result</entry>
607       </row>
608      </thead>
609
610      <tbody>
611       <row>
612        <entry> <literal>+</literal> </entry>
613        <entry>addition</entry>
614        <entry><literal>2 + 3</literal></entry>
615        <entry><literal>5</literal></entry>
616       </row>
617
618       <row>
619        <entry> <literal>-</literal> </entry>
620        <entry>subtraction</entry>
621        <entry><literal>2 - 3</literal></entry>
622        <entry><literal>-1</literal></entry>
623       </row>
624
625       <row>
626        <entry> <literal>*</literal> </entry>
627        <entry>multiplication</entry>
628        <entry><literal>2 * 3</literal></entry>
629        <entry><literal>6</literal></entry>
630       </row>
631
632       <row>
633        <entry> <literal>/</literal> </entry>
634        <entry>division (integer division truncates the result)</entry>
635        <entry><literal>4 / 2</literal></entry>
636        <entry><literal>2</literal></entry>
637       </row>
638
639       <row>
640        <entry> <literal>%</literal> </entry>
641        <entry>modulo (remainder)</entry>
642        <entry><literal>5 % 4</literal></entry>
643        <entry><literal>1</literal></entry>
644       </row>
645
646       <row>
647        <entry> <literal>^</literal> </entry>
648        <entry>exponentiation (associates left to right)</entry>
649        <entry><literal>2.0 ^ 3.0</literal></entry>
650        <entry><literal>8</literal></entry>
651       </row>
652
653       <row>
654        <entry> <literal>|/</literal> </entry>
655        <entry>square root</entry>
656        <entry><literal>|/ 25.0</literal></entry>
657        <entry><literal>5</literal></entry>
658       </row>
659
660       <row>
661        <entry> <literal>||/</literal> </entry>
662        <entry>cube root</entry>
663        <entry><literal>||/ 27.0</literal></entry>
664        <entry><literal>3</literal></entry>
665       </row>
666
667       <row>
668        <entry> <literal>!</literal> </entry>
669        <entry>factorial</entry>
670        <entry><literal>5 !</literal></entry>
671        <entry><literal>120</literal></entry>
672       </row>
673
674       <row>
675        <entry> <literal>!!</literal> </entry>
676        <entry>factorial (prefix operator)</entry>
677        <entry><literal>!! 5</literal></entry>
678        <entry><literal>120</literal></entry>
679       </row>
680
681       <row>
682        <entry> <literal>@</literal> </entry>
683        <entry>absolute value</entry>
684        <entry><literal>@ -5.0</literal></entry>
685        <entry><literal>5</literal></entry>
686       </row>
687
688       <row>
689        <entry> <literal>&amp;</literal> </entry>
690        <entry>bitwise AND</entry>
691        <entry><literal>91 &amp; 15</literal></entry>
692        <entry><literal>11</literal></entry>
693       </row>
694
695       <row>
696        <entry> <literal>|</literal> </entry>
697        <entry>bitwise OR</entry>
698        <entry><literal>32 | 3</literal></entry>
699        <entry><literal>35</literal></entry>
700       </row>
701
702       <row>
703        <entry> <literal>#</literal> </entry>
704        <entry>bitwise XOR</entry>
705        <entry><literal>17 # 5</literal></entry>
706        <entry><literal>20</literal></entry>
707       </row>
708
709       <row>
710        <entry> <literal>~</literal> </entry>
711        <entry>bitwise NOT</entry>
712        <entry><literal>~1</literal></entry>
713        <entry><literal>-2</literal></entry>
714       </row>
715
716       <row>
717        <entry> <literal>&lt;&lt;</literal> </entry>
718        <entry>bitwise shift left</entry>
719        <entry><literal>1 &lt;&lt; 4</literal></entry>
720        <entry><literal>16</literal></entry>
721       </row>
722
723       <row>
724        <entry> <literal>&gt;&gt;</literal> </entry>
725        <entry>bitwise shift right</entry>
726        <entry><literal>8 &gt;&gt; 2</literal></entry>
727        <entry><literal>2</literal></entry>
728       </row>
729
730      </tbody>
731     </tgroup>
732    </table>
733
734    <para>
735     The bitwise operators work only on integral data types, whereas
736     the others are available for all numeric data types.  The bitwise
737     operators are also available for the bit
738     string types <type>bit</type> and <type>bit varying</type>, as
739     shown in <xref linkend="functions-bit-string-op-table">.
740    </para>
741
742   <para>
743    <xref linkend="functions-math-func-table"> shows the available
744    mathematical functions.  In the table, <literal>dp</literal>
745    indicates <type>double precision</type>.  Many of these functions
746    are provided in multiple forms with different argument types.
747    Except where noted, any given form of a function returns the same
748    data type as its argument.
749    The functions working with <type>double precision</type> data are mostly
750    implemented on top of the host system's C library; accuracy and behavior in
751    boundary cases can therefore vary depending on the host system.
752   </para>
753
754    <table id="functions-math-func-table">
755     <title>Mathematical Functions</title>
756     <tgroup cols="5">
757      <thead>
758       <row>
759        <entry>Function</entry>
760        <entry>Return Type</entry>
761        <entry>Description</entry>
762        <entry>Example</entry>
763        <entry>Result</entry>
764       </row>
765      </thead>
766
767      <tbody>
768       <row>
769        <entry>
770         <indexterm>
771          <primary>abs</primary>
772         </indexterm>
773         <literal><function>abs(<replaceable>x</replaceable>)</function></literal>
774        </entry>
775        <entry>(same as input)</entry>
776        <entry>absolute value</entry>
777        <entry><literal>abs(-17.4)</literal></entry>
778        <entry><literal>17.4</literal></entry>
779       </row>
780
781       <row>
782        <entry>
783         <indexterm>
784          <primary>cbrt</primary>
785         </indexterm>
786         <literal><function>cbrt(<type>dp</type>)</function></literal>
787        </entry>
788        <entry><type>dp</type></entry>
789        <entry>cube root</entry>
790        <entry><literal>cbrt(27.0)</literal></entry>
791        <entry><literal>3</literal></entry>
792       </row>
793
794       <row>
795        <entry>
796         <indexterm>
797          <primary>ceil</primary>
798         </indexterm>
799         <literal><function>ceil(<type>dp</type> or <type>numeric</type>)</function></literal>
800        </entry>
801        <entry>(same as input)</entry>
802        <entry>nearest integer greater than or equal to argument</entry>
803        <entry><literal>ceil(-42.8)</literal></entry>
804        <entry><literal>-42</literal></entry>
805       </row>
806
807       <row>
808        <entry>
809         <indexterm>
810          <primary>ceiling</primary>
811         </indexterm>
812         <literal><function>ceiling(<type>dp</type> or <type>numeric</type>)</function></literal>
813        </entry>
814        <entry>(same as input)</entry>
815        <entry>nearest integer greater than or equal to argument (same as <function>ceil</function>)</entry>
816        <entry><literal>ceiling(-95.3)</literal></entry>
817        <entry><literal>-95</literal></entry>
818       </row>
819
820       <row>
821        <entry>
822         <indexterm>
823          <primary>degrees</primary>
824         </indexterm>
825         <literal><function>degrees(<type>dp</type>)</function></literal>
826        </entry>
827        <entry><type>dp</type></entry>
828        <entry>radians to degrees</entry>
829        <entry><literal>degrees(0.5)</literal></entry>
830        <entry><literal>28.6478897565412</literal></entry>
831       </row>
832
833       <row>
834        <entry>
835         <indexterm>
836          <primary>div</primary>
837         </indexterm>
838         <literal><function>div(<parameter>y</parameter> <type>numeric</>,
839          <parameter>x</parameter> <type>numeric</>)</function></literal>
840        </entry>
841        <entry><type>numeric</></entry>
842        <entry>integer quotient of <parameter>y</parameter>/<parameter>x</parameter></entry>
843        <entry><literal>div(9,4)</literal></entry>
844        <entry><literal>2</literal></entry>
845       </row>
846
847       <row>
848        <entry>
849         <indexterm>
850          <primary>exp</primary>
851         </indexterm>
852         <literal><function>exp(<type>dp</type> or <type>numeric</type>)</function></literal>
853        </entry>
854        <entry>(same as input)</entry>
855        <entry>exponential</entry>
856        <entry><literal>exp(1.0)</literal></entry>
857        <entry><literal>2.71828182845905</literal></entry>
858       </row>
859
860       <row>
861        <entry>
862         <indexterm>
863          <primary>floor</primary>
864         </indexterm>
865         <literal><function>floor(<type>dp</type> or <type>numeric</type>)</function></literal>
866        </entry>
867        <entry>(same as input)</entry>
868        <entry>nearest integer less than or equal to argument</entry>
869        <entry><literal>floor(-42.8)</literal></entry>
870        <entry><literal>-43</literal></entry>
871       </row>
872
873       <row>
874        <entry>
875         <indexterm>
876          <primary>ln</primary>
877         </indexterm>
878         <literal><function>ln(<type>dp</type> or <type>numeric</type>)</function></literal>
879        </entry>
880        <entry>(same as input)</entry>
881        <entry>natural logarithm</entry>
882        <entry><literal>ln(2.0)</literal></entry>
883        <entry><literal>0.693147180559945</literal></entry>
884       </row>
885
886       <row>
887        <entry>
888         <indexterm>
889          <primary>log</primary>
890         </indexterm>
891         <literal><function>log(<type>dp</type> or <type>numeric</type>)</function></literal>
892        </entry>
893        <entry>(same as input)</entry>
894        <entry>base 10 logarithm</entry>
895        <entry><literal>log(100.0)</literal></entry>
896        <entry><literal>2</literal></entry>
897       </row>
898
899       <row>
900        <entry><literal><function>log(<parameter>b</parameter> <type>numeric</type>,
901         <parameter>x</parameter> <type>numeric</type>)</function></literal></entry>
902        <entry><type>numeric</type></entry>
903        <entry>logarithm to base <parameter>b</parameter></entry>
904        <entry><literal>log(2.0, 64.0)</literal></entry>
905        <entry><literal>6.0000000000</literal></entry>
906       </row>
907
908       <row>
909        <entry>
910         <indexterm>
911          <primary>mod</primary>
912         </indexterm>
913         <literal><function>mod(<parameter>y</parameter>,
914          <parameter>x</parameter>)</function></literal>
915        </entry>
916        <entry>(same as argument types)</entry>
917        <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
918        <entry><literal>mod(9,4)</literal></entry>
919        <entry><literal>1</literal></entry>
920       </row>
921
922       <row>
923        <entry>
924         <indexterm>
925          <primary>pi</primary>
926         </indexterm>
927         <literal><function>pi()</function></literal>
928        </entry>
929        <entry><type>dp</type></entry>
930        <entry><quote>&pi;</quote> constant</entry>
931        <entry><literal>pi()</literal></entry>
932        <entry><literal>3.14159265358979</literal></entry>
933       </row>
934
935       <row>
936        <entry>
937         <indexterm>
938          <primary>power</primary>
939         </indexterm>
940         <literal><function>power(<parameter>a</parameter> <type>dp</type>,
941         <parameter>b</parameter> <type>dp</type>)</function></literal>
942        </entry>
943        <entry><type>dp</type></entry>
944        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
945        <entry><literal>power(9.0, 3.0)</literal></entry>
946        <entry><literal>729</literal></entry>
947       </row>
948
949       <row>
950        <entry><literal><function>power(<parameter>a</parameter> <type>numeric</type>,
951         <parameter>b</parameter> <type>numeric</type>)</function></literal></entry>
952        <entry><type>numeric</type></entry>
953        <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
954        <entry><literal>power(9.0, 3.0)</literal></entry>
955        <entry><literal>729</literal></entry>
956       </row>
957
958       <row>
959        <entry>
960         <indexterm>
961          <primary>radians</primary>
962         </indexterm>
963         <literal><function>radians(<type>dp</type>)</function></literal>
964        </entry>
965        <entry><type>dp</type></entry>
966        <entry>degrees to radians</entry>
967        <entry><literal>radians(45.0)</literal></entry>
968        <entry><literal>0.785398163397448</literal></entry>
969       </row>
970
971       <row>
972        <entry>
973         <indexterm>
974          <primary>round</primary>
975         </indexterm>
976         <literal><function>round(<type>dp</type> or <type>numeric</type>)</function></literal>
977        </entry>
978        <entry>(same as input)</entry>
979        <entry>round to nearest integer</entry>
980        <entry><literal>round(42.4)</literal></entry>
981        <entry><literal>42</literal></entry>
982       </row>
983
984       <row>
985        <entry><literal><function>round(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
986        <entry><type>numeric</type></entry>
987        <entry>round to <parameter>s</parameter> decimal places</entry>
988        <entry><literal>round(42.4382, 2)</literal></entry>
989        <entry><literal>42.44</literal></entry>
990       </row>
991
992       <row>
993        <entry>
994         <indexterm>
995          <primary>scale</primary>
996         </indexterm>
997         <literal><function>scale(<type>numeric</type>)</function></literal>
998        </entry>
999        <entry><type>numeric</type></entry>
1000        <entry>scale of the argument (the number of decimal digits in the fractional part)</entry>
1001        <entry><literal>scale(8.41)</literal></entry>
1002        <entry><literal>2</literal></entry>
1003       </row>
1004
1005       <row>
1006        <entry>
1007         <indexterm>
1008          <primary>sign</primary>
1009         </indexterm>
1010         <literal><function>sign(<type>dp</type> or <type>numeric</type>)</function></literal>
1011        </entry>
1012        <entry>(same as input)</entry>
1013        <entry>sign of the argument (-1, 0, +1)</entry>
1014        <entry><literal>sign(-8.4)</literal></entry>
1015        <entry><literal>-1</literal></entry>
1016       </row>
1017
1018       <row>
1019        <entry>
1020         <indexterm>
1021          <primary>sqrt</primary>
1022         </indexterm>
1023         <literal><function>sqrt(<type>dp</type> or <type>numeric</type>)</function></literal>
1024        </entry>
1025        <entry>(same as input)</entry>
1026        <entry>square root</entry>
1027        <entry><literal>sqrt(2.0)</literal></entry>
1028        <entry><literal>1.4142135623731</literal></entry>
1029       </row>
1030
1031       <row>
1032        <entry>
1033         <indexterm>
1034          <primary>trunc</primary>
1035         </indexterm>
1036         <literal><function>trunc(<type>dp</type> or <type>numeric</type>)</function></literal>
1037        </entry>
1038        <entry>(same as input)</entry>
1039        <entry>truncate toward zero</entry>
1040        <entry><literal>trunc(42.8)</literal></entry>
1041        <entry><literal>42</literal></entry>
1042       </row>
1043
1044       <row>
1045        <entry><literal><function>trunc(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
1046        <entry><type>numeric</type></entry>
1047        <entry>truncate to <parameter>s</parameter> decimal places</entry>
1048        <entry><literal>trunc(42.4382, 2)</literal></entry>
1049        <entry><literal>42.43</literal></entry>
1050       </row>
1051
1052       <row>
1053        <entry>
1054         <indexterm>
1055          <primary>width_bucket</primary>
1056         </indexterm>
1057         <literal><function>width_bucket(<parameter>operand</parameter> <type>dp</type>, <parameter>b1</parameter> <type>dp</type>, <parameter>b2</parameter> <type>dp</type>, <parameter>count</parameter> <type>int</type>)</function></literal></entry>
1058        <entry><type>int</type></entry>
1059        <entry>return the bucket number to which <parameter>operand</> would
1060        be assigned in a histogram having <parameter>count</> equal-width
1061        buckets spanning the range <parameter>b1</> to <parameter>b2</>;
1062        returns <literal>0</> or <literal><parameter>count</>+1</literal> for
1063        an input outside the range</entry>
1064        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
1065        <entry><literal>3</literal></entry>
1066       </row>
1067
1068       <row>
1069        <entry><literal><function>width_bucket(<parameter>operand</parameter> <type>numeric</type>, <parameter>b1</parameter> <type>numeric</type>, <parameter>b2</parameter> <type>numeric</type>, <parameter>count</parameter> <type>int</type>)</function></literal></entry>
1070        <entry><type>int</type></entry>
1071        <entry>return the bucket number to which <parameter>operand</> would
1072        be assigned in a histogram having <parameter>count</> equal-width
1073        buckets spanning the range <parameter>b1</> to <parameter>b2</>;
1074        returns <literal>0</> or <literal><parameter>count</>+1</literal> for
1075        an input outside the range</entry>
1076        <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
1077        <entry><literal>3</literal></entry>
1078       </row>
1079
1080       <row>
1081        <entry><literal><function>width_bucket(<parameter>operand</parameter> <type>anyelement</type>, <parameter>thresholds</parameter> <type>anyarray</type>)</function></literal></entry>
1082        <entry><type>int</type></entry>
1083        <entry>return the bucket number to which <parameter>operand</> would
1084        be assigned given an array listing the lower bounds of the buckets;
1085        returns <literal>0</> for an input less than the first lower bound;
1086        the <parameter>thresholds</> array <emphasis>must be sorted</>,
1087        smallest first, or unexpected results will be obtained</entry>
1088        <entry><literal>width_bucket(now(), array['yesterday', 'today', 'tomorrow']::timestamptz[])</literal></entry>
1089        <entry><literal>2</literal></entry>
1090       </row>
1091      </tbody>
1092     </tgroup>
1093    </table>
1094
1095   <para>
1096     <xref linkend="functions-math-random-table"> shows functions for
1097     generating random numbers.
1098   </para>
1099
1100    <table id="functions-math-random-table">
1101     <title>Random Functions</title>
1102
1103     <tgroup cols="3">
1104      <thead>
1105       <row>
1106        <entry>Function</entry>
1107        <entry>Return Type</entry>
1108        <entry>Description</entry>
1109       </row>
1110      </thead>
1111      <tbody>
1112       <row>
1113        <entry>
1114         <indexterm>
1115          <primary>random</primary>
1116         </indexterm>
1117         <literal><function>random()</function></literal>
1118        </entry>
1119        <entry><type>dp</type></entry>
1120        <entry>random value in the range 0.0 &lt;= x &lt; 1.0</entry>
1121       </row>
1122
1123       <row>
1124        <entry>
1125         <indexterm>
1126          <primary>setseed</primary>
1127         </indexterm>
1128         <literal><function>setseed(<type>dp</type>)</function></literal>
1129        </entry>
1130        <entry><type>void</type></entry>
1131        <entry>set seed for subsequent <literal>random()</literal> calls (value between -1.0 and
1132        1.0, inclusive)</entry>
1133       </row>
1134      </tbody>
1135     </tgroup>
1136    </table>
1137
1138   <para>
1139    The characteristics of the values returned by
1140    <literal><function>random()</function></literal> depend
1141    on the system implementation. It is not suitable for cryptographic
1142    applications; see <xref linkend="pgcrypto"> module for an alternative.
1143    </para>
1144
1145   <para>
1146    Finally, <xref linkend="functions-math-trig-table"> shows the
1147    available trigonometric functions.  All trigonometric functions
1148    take arguments and return values of type <type>double
1149    precision</type>.  Each of the trigonometric functions comes in
1150    two variants, one that measures angles in radians and one that
1151    measures angles in degrees.
1152   </para>
1153
1154    <table id="functions-math-trig-table">
1155     <title>Trigonometric Functions</title>
1156
1157     <tgroup cols="3">
1158      <thead>
1159       <row>
1160        <entry>Function (radians)</entry>
1161        <entry>Function (degrees)</entry>
1162        <entry>Description</entry>
1163       </row>
1164      </thead>
1165
1166      <tbody>
1167       <row>
1168        <entry>
1169         <indexterm>
1170          <primary>acos</primary>
1171         </indexterm><literal><function>acos(<replaceable>x</replaceable>)</function></literal>
1172        </entry>
1173        <entry>
1174         <indexterm>
1175          <primary>acosd</primary>
1176         </indexterm><literal><function>acosd(<replaceable>x</replaceable>)</function></literal>
1177        </entry>
1178        <entry>inverse cosine</entry>
1179       </row>
1180
1181       <row>
1182        <entry>
1183         <indexterm>
1184          <primary>asin</primary>
1185         </indexterm>
1186         <literal><function>asin(<replaceable>x</replaceable>)</function></literal>
1187        </entry>
1188        <entry>
1189         <indexterm>
1190          <primary>asind</primary>
1191         </indexterm>
1192         <literal><function>asind(<replaceable>x</replaceable>)</function></literal>
1193        </entry>
1194        <entry>inverse sine</entry>
1195       </row>
1196
1197       <row>
1198        <entry>
1199         <indexterm>
1200          <primary>atan</primary>
1201         </indexterm>
1202         <literal><function>atan(<replaceable>x</replaceable>)</function></literal>
1203        </entry>
1204        <entry>
1205         <indexterm>
1206          <primary>atand</primary>
1207         </indexterm>
1208         <literal><function>atand(<replaceable>x</replaceable>)</function></literal>
1209        </entry>
1210        <entry>inverse tangent</entry>
1211       </row>
1212
1213       <row>
1214        <entry>
1215         <indexterm>
1216          <primary>atan2</primary>
1217         </indexterm>
1218         <literal><function>atan2(<replaceable>y</replaceable>,
1219         <replaceable>x</replaceable>)</function></literal>
1220        </entry>
1221        <entry>
1222         <indexterm>
1223          <primary>atan2d</primary>
1224         </indexterm>
1225         <literal><function>atan2d(<replaceable>y</replaceable>,
1226         <replaceable>x</replaceable>)</function></literal>
1227        </entry>
1228        <entry>inverse tangent of
1229         <literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
1230       </row>
1231
1232       <row>
1233        <entry>
1234         <indexterm>
1235          <primary>cos</primary>
1236         </indexterm>
1237         <literal><function>cos(<replaceable>x</replaceable>)</function></literal>
1238        </entry>
1239        <entry>
1240         <indexterm>
1241          <primary>cosd</primary>
1242         </indexterm>
1243         <literal><function>cosd(<replaceable>x</replaceable>)</function></literal>
1244        </entry>
1245        <entry>cosine</entry>
1246       </row>
1247
1248       <row>
1249        <entry>
1250         <indexterm>
1251          <primary>cot</primary>
1252         </indexterm>
1253         <literal><function>cot(<replaceable>x</replaceable>)</function></literal>
1254        </entry>
1255        <entry>
1256         <indexterm>
1257          <primary>cotd</primary>
1258         </indexterm>
1259         <literal><function>cotd(<replaceable>x</replaceable>)</function></literal>
1260        </entry>
1261        <entry>cotangent</entry>
1262       </row>
1263
1264       <row>
1265        <entry>
1266         <indexterm>
1267          <primary>sin</primary>
1268         </indexterm>
1269         <literal><function>sin(<replaceable>x</replaceable>)</function></literal>
1270        </entry>
1271        <entry>
1272         <indexterm>
1273          <primary>sind</primary>
1274         </indexterm>
1275         <literal><function>sind(<replaceable>x</replaceable>)</function></literal>
1276        </entry>
1277        <entry>sine</entry>
1278       </row>
1279
1280       <row>
1281        <entry>
1282         <indexterm>
1283          <primary>tan</primary>
1284         </indexterm>
1285         <literal><function>tan(<replaceable>x</replaceable>)</function></literal>
1286        </entry>
1287        <entry>
1288         <indexterm>
1289          <primary>tand</primary>
1290         </indexterm>
1291         <literal><function>tand(<replaceable>x</replaceable>)</function></literal>
1292        </entry>
1293        <entry>tangent</entry>
1294       </row>
1295      </tbody>
1296     </tgroup>
1297    </table>
1298
1299   <note>
1300    <para>
1301     Another way to work with angles measured in degrees is to use the unit
1302     transformation functions <literal><function>radians()</function></literal>
1303     and <literal><function>degrees()</function></literal> shown earlier.
1304     However, using the degree-based trigonometric functions is preferred,
1305     as that way avoids roundoff error for special cases such
1306     as <literal>sind(30)</>.
1307    </para>
1308   </note>
1309
1310   </sect1>
1311
1312
1313   <sect1 id="functions-string">
1314    <title>String Functions and Operators</title>
1315
1316    <para>
1317     This section describes functions and operators for examining and
1318     manipulating string values.  Strings in this context include values
1319     of the types <type>character</type>, <type>character varying</type>,
1320     and <type>text</type>.  Unless otherwise noted, all
1321     of the functions listed below work on all of these types, but be
1322     wary of potential effects of automatic space-padding when using the
1323     <type>character</type> type.  Some functions also exist
1324     natively for the bit-string types.
1325    </para>
1326
1327    <para>
1328     <acronym>SQL</acronym> defines some string functions that use
1329     key words, rather than commas, to separate
1330     arguments.  Details are in
1331     <xref linkend="functions-string-sql">.
1332     <productname>PostgreSQL</> also provides versions of these functions
1333     that use the regular function invocation syntax
1334     (see <xref linkend="functions-string-other">).
1335    </para>
1336
1337    <note>
1338     <para>
1339      Before <productname>PostgreSQL</productname> 8.3, these functions would
1340      silently accept values of several non-string data types as well, due to
1341      the presence of implicit coercions from those data types to
1342      <type>text</>.  Those coercions have been removed because they frequently
1343      caused surprising behaviors.  However, the string concatenation operator
1344      (<literal>||</>) still accepts non-string input, so long as at least one
1345      input is of a string type, as shown in <xref
1346      linkend="functions-string-sql">.  For other cases, insert an explicit
1347      coercion to <type>text</> if you need to duplicate the previous behavior.
1348     </para>
1349    </note>
1350
1351    <table id="functions-string-sql">
1352     <title><acronym>SQL</acronym> String Functions and Operators</title>
1353     <tgroup cols="5">
1354      <thead>
1355       <row>
1356        <entry>Function</entry>
1357        <entry>Return Type</entry>
1358        <entry>Description</entry>
1359        <entry>Example</entry>
1360        <entry>Result</entry>
1361       </row>
1362      </thead>
1363
1364      <tbody>
1365       <row>
1366        <entry><literal><parameter>string</parameter> <literal>||</literal>
1367         <parameter>string</parameter></literal></entry>
1368        <entry> <type>text</type> </entry>
1369        <entry>
1370         String concatenation
1371         <indexterm>
1372          <primary>character string</primary>
1373          <secondary>concatenation</secondary>
1374         </indexterm>
1375        </entry>
1376        <entry><literal>'Post' || 'greSQL'</literal></entry>
1377        <entry><literal>PostgreSQL</literal></entry>
1378       </row>
1379
1380       <row>
1381        <entry>
1382         <literal><parameter>string</parameter> <literal>||</literal>
1383         <parameter>non-string</parameter></literal>
1384         or
1385         <literal><parameter>non-string</parameter> <literal>||</literal>
1386         <parameter>string</parameter></literal>
1387        </entry>
1388        <entry> <type>text</type> </entry>
1389        <entry>
1390         String concatenation with one non-string input
1391        </entry>
1392        <entry><literal>'Value: ' || 42</literal></entry>
1393        <entry><literal>Value: 42</literal></entry>
1394       </row>
1395
1396       <row>
1397        <entry>
1398         <indexterm>
1399          <primary>bit_length</primary>
1400         </indexterm>
1401         <literal><function>bit_length(<parameter>string</parameter>)</function></literal>
1402        </entry>
1403        <entry><type>int</type></entry>
1404        <entry>Number of bits in string</entry>
1405        <entry><literal>bit_length('jose')</literal></entry>
1406        <entry><literal>32</literal></entry>
1407       </row>
1408
1409       <row>
1410        <entry>
1411         <indexterm>
1412          <primary>char_length</primary>
1413         </indexterm>
1414         <literal><function>char_length(<parameter>string</parameter>)</function></literal> or <literal><function>character_length(<parameter>string</parameter>)</function></literal>
1415        </entry>
1416        <entry><type>int</type></entry>
1417        <entry>
1418         Number of characters in string
1419         <indexterm>
1420          <primary>character string</primary>
1421          <secondary>length</secondary>
1422         </indexterm>
1423         <indexterm>
1424          <primary>length</primary>
1425          <secondary sortas="character string">of a character string</secondary>
1426          <see>character string, length</see>
1427         </indexterm>
1428        </entry>
1429        <entry><literal>char_length('jose')</literal></entry>
1430        <entry><literal>4</literal></entry>
1431       </row>
1432
1433       <row>
1434        <entry>
1435         <indexterm>
1436          <primary>lower</primary>
1437         </indexterm>
1438         <literal><function>lower(<parameter>string</parameter>)</function></literal>
1439        </entry>
1440        <entry><type>text</type></entry>
1441        <entry>Convert string to lower case</entry>
1442        <entry><literal>lower('TOM')</literal></entry>
1443        <entry><literal>tom</literal></entry>
1444       </row>
1445
1446       <row>
1447        <entry>
1448         <indexterm>
1449          <primary>octet_length</primary>
1450         </indexterm>
1451         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
1452        </entry>
1453        <entry><type>int</type></entry>
1454        <entry>Number of bytes in string</entry>
1455        <entry><literal>octet_length('jose')</literal></entry>
1456        <entry><literal>4</literal></entry>
1457       </row>
1458
1459       <row>
1460        <entry>
1461         <indexterm>
1462          <primary>overlay</primary>
1463         </indexterm>
1464         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
1465        </entry>
1466        <entry><type>text</type></entry>
1467        <entry>
1468         Replace substring
1469        </entry>
1470        <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
1471        <entry><literal>Thomas</literal></entry>
1472       </row>
1473
1474       <row>
1475        <entry>
1476         <indexterm>
1477          <primary>position</primary>
1478         </indexterm>
1479         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
1480        </entry>
1481        <entry><type>int</type></entry>
1482        <entry>Location of specified substring</entry>
1483        <entry><literal>position('om' in 'Thomas')</literal></entry>
1484        <entry><literal>3</literal></entry>
1485       </row>
1486
1487       <row>
1488        <entry>
1489         <indexterm>
1490          <primary>substring</primary>
1491         </indexterm>
1492         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
1493        </entry>
1494        <entry><type>text</type></entry>
1495        <entry>
1496         Extract substring
1497        </entry>
1498        <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
1499        <entry><literal>hom</literal></entry>
1500       </row>
1501
1502       <row>
1503        <entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</function></literal></entry>
1504        <entry><type>text</type></entry>
1505        <entry>
1506         Extract substring matching POSIX regular expression. See
1507         <xref linkend="functions-matching"> for more information on pattern
1508         matching.
1509        </entry>
1510        <entry><literal>substring('Thomas' from '...$')</literal></entry>
1511        <entry><literal>mas</literal></entry>
1512       </row>
1513
1514       <row>
1515        <entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</function></literal></entry>
1516        <entry><type>text</type></entry>
1517        <entry>
1518         Extract substring matching <acronym>SQL</acronym> regular expression.
1519         See <xref linkend="functions-matching"> for more information on
1520         pattern matching.
1521        </entry>
1522        <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
1523        <entry><literal>oma</literal></entry>
1524       </row>
1525
1526       <row>
1527        <entry>
1528         <indexterm>
1529          <primary>trim</primary>
1530         </indexterm>
1531         <literal><function>trim(<optional>leading | trailing | both</optional>
1532         <optional><parameter>characters</parameter></optional> from
1533         <parameter>string</parameter>)</function></literal>
1534        </entry>
1535        <entry><type>text</type></entry>
1536        <entry>
1537         Remove the longest string containing only characters from
1538         <parameter>characters</parameter> (a space by default) from the
1539         start, end, or both ends (<literal>both</> is the default)
1540         of <parameter>string</parameter>
1541        </entry>
1542        <entry><literal>trim(both 'xyz' from 'yxTomxx')</literal></entry>
1543        <entry><literal>Tom</literal></entry>
1544       </row>
1545
1546       <row>
1547        <entry>
1548         <literal><function>trim(<optional>leading | trailing
1549         | both</optional> <optional>from</optional>
1550         <parameter>string</parameter>
1551         <optional>, <parameter>characters</parameter></optional>
1552         )</function></literal>
1553        </entry>
1554        <entry><type>text</type></entry>
1555        <entry>
1556         Non-standard syntax for <function>trim()</>
1557        </entry>
1558        <entry><literal>trim(both from 'yxTomxx', 'xyz')</literal></entry>
1559        <entry><literal>Tom</literal></entry>
1560       </row>
1561
1562       <row>
1563        <entry>
1564         <indexterm>
1565          <primary>upper</primary>
1566         </indexterm>
1567         <literal><function>upper(<parameter>string</parameter>)</function></literal>
1568        </entry>
1569        <entry><type>text</type></entry>
1570        <entry>Convert string to upper case</entry>
1571        <entry><literal>upper('tom')</literal></entry>
1572        <entry><literal>TOM</literal></entry>
1573       </row>
1574      </tbody>
1575     </tgroup>
1576    </table>
1577
1578    <para>
1579     Additional string manipulation functions are available and are
1580     listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
1581     <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
1582    </para>
1583
1584    <table id="functions-string-other">
1585     <title>Other String Functions</title>
1586     <tgroup cols="5">
1587      <thead>
1588       <row>
1589        <entry>Function</entry>
1590        <entry>Return Type</entry>
1591        <entry>Description</entry>
1592        <entry>Example</entry>
1593        <entry>Result</entry>
1594       </row>
1595      </thead>
1596
1597      <tbody>
1598       <row>
1599        <entry>
1600         <indexterm>
1601          <primary>ascii</primary>
1602         </indexterm>
1603         <literal><function>ascii(<parameter>string</parameter>)</function></literal>
1604        </entry>
1605        <entry><type>int</type></entry>
1606        <entry>
1607         <acronym>ASCII</acronym> code of the first character of the
1608         argument.  For <acronym>UTF8</acronym> returns the Unicode code
1609         point of the character.  For other multibyte encodings, the
1610         argument must be an <acronym>ASCII</acronym> character.
1611        </entry>
1612        <entry><literal>ascii('x')</literal></entry>
1613        <entry><literal>120</literal></entry>
1614       </row>
1615
1616       <row>
1617        <entry>
1618         <indexterm>
1619          <primary>btrim</primary>
1620         </indexterm>
1621         <literal><function>btrim(<parameter>string</parameter> <type>text</type>
1622         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1623        </entry>
1624        <entry><type>text</type></entry>
1625        <entry>
1626         Remove the longest string consisting only of characters
1627         in <parameter>characters</parameter> (a space by default)
1628         from the start and end of <parameter>string</parameter>
1629        </entry>
1630        <entry><literal>btrim('xyxtrimyyx', 'xyz')</literal></entry>
1631        <entry><literal>trim</literal></entry>
1632       </row>
1633
1634       <row>
1635        <entry>
1636         <indexterm>
1637          <primary>chr</primary>
1638         </indexterm>
1639         <literal><function>chr(<type>int</type>)</function></literal>
1640        </entry>
1641        <entry><type>text</type></entry>
1642        <entry>
1643         Character with the given code. For <acronym>UTF8</acronym> the
1644         argument is treated as a Unicode code point. For other multibyte
1645         encodings the argument must designate an
1646         <acronym>ASCII</acronym> character.  The NULL (0) character is not
1647         allowed because text data types cannot store such bytes.
1648        </entry>
1649        <entry><literal>chr(65)</literal></entry>
1650        <entry><literal>A</literal></entry>
1651       </row>
1652
1653       <row>
1654        <entry>
1655         <indexterm>
1656          <primary>concat</primary>
1657         </indexterm>
1658         <literal><function>concat(<parameter>str</parameter> <type>"any"</type>
1659          [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
1660        </entry>
1661        <entry><type>text</type></entry>
1662        <entry>
1663         Concatenate the text representations of all the arguments.
1664         NULL arguments are ignored.
1665        </entry>
1666        <entry><literal>concat('abcde', 2, NULL, 22)</literal></entry>
1667        <entry><literal>abcde222</literal></entry>
1668       </row>
1669
1670       <row>
1671        <entry>
1672         <indexterm>
1673          <primary>concat_ws</primary>
1674         </indexterm>
1675         <literal><function>concat_ws(<parameter>sep</parameter> <type>text</type>,
1676         <parameter>str</parameter> <type>"any"</type>
1677         [, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
1678        </entry>
1679        <entry><type>text</type></entry>
1680        <entry>
1681         Concatenate all but the first argument with separators. The first
1682         argument is used as the separator string. NULL arguments are ignored.
1683        </entry>
1684        <entry><literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal></entry>
1685        <entry><literal>abcde,2,22</literal></entry>
1686       </row>
1687
1688       <row>
1689        <entry>
1690         <indexterm>
1691          <primary>convert</primary>
1692         </indexterm>
1693         <literal><function>convert(<parameter>string</parameter> <type>bytea</type>,
1694         <parameter>src_encoding</parameter> <type>name</type>,
1695         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1696        </entry>
1697        <entry><type>bytea</type></entry>
1698        <entry>
1699         Convert string to <parameter>dest_encoding</parameter>.  The
1700         original encoding is specified by
1701         <parameter>src_encoding</parameter>. The
1702         <parameter>string</parameter> must be valid in this encoding.
1703         Conversions can be defined by <command>CREATE CONVERSION</command>.
1704         Also there are some predefined conversions. See <xref
1705         linkend="conversion-names"> for available conversions.
1706        </entry>
1707        <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1708        <entry><literal>text_in_utf8</literal> represented in Latin-1
1709        encoding (ISO 8859-1)</entry>
1710       </row>
1711
1712       <row>
1713        <entry>
1714         <indexterm>
1715          <primary>convert_from</primary>
1716         </indexterm>
1717         <literal><function>convert_from(<parameter>string</parameter> <type>bytea</type>,
1718         <parameter>src_encoding</parameter> <type>name</type>)</function></literal>
1719        </entry>
1720        <entry><type>text</type></entry>
1721        <entry>
1722         Convert string to the database encoding.  The original encoding
1723         is specified by <parameter>src_encoding</parameter>. The
1724         <parameter>string</parameter> must be valid in this encoding.
1725        </entry>
1726        <entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
1727        <entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
1728       </row>
1729
1730       <row>
1731        <entry>
1732         <indexterm>
1733          <primary>convert_to</primary>
1734         </indexterm>
1735         <literal><function>convert_to(<parameter>string</parameter> <type>text</type>,
1736         <parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
1737        </entry>
1738        <entry><type>bytea</type></entry>
1739        <entry>
1740         Convert string to <parameter>dest_encoding</parameter>.
1741        </entry>
1742        <entry><literal>convert_to('some text', 'UTF8')</literal></entry>
1743        <entry><literal>some text</literal> represented in the UTF8 encoding</entry>
1744       </row>
1745
1746       <row>
1747        <entry>
1748         <indexterm>
1749          <primary>decode</primary>
1750         </indexterm>
1751         <literal><function>decode(<parameter>string</parameter> <type>text</type>,
1752         <parameter>format</parameter> <type>text</type>)</function></literal>
1753        </entry>
1754        <entry><type>bytea</type></entry>
1755        <entry>
1756         Decode binary data from textual representation in <parameter>string</>.
1757         Options for <parameter>format</> are same as in <function>encode</>.
1758        </entry>
1759        <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
1760        <entry><literal>\x3132330001</literal></entry>
1761       </row>
1762
1763       <row>
1764        <entry>
1765         <indexterm>
1766          <primary>encode</primary>
1767         </indexterm>
1768         <literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
1769         <parameter>format</parameter> <type>text</type>)</function></literal>
1770        </entry>
1771        <entry><type>text</type></entry>
1772        <entry>
1773         Encode binary data into a textual representation.  Supported
1774         formats are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
1775         <literal>escape</> converts zero bytes and high-bit-set bytes to
1776         octal sequences (<literal>\</><replaceable>nnn</>) and
1777         doubles backslashes.
1778        </entry>
1779        <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1780        <entry><literal>MTIzAAE=</literal></entry>
1781       </row>
1782
1783       <row>
1784        <entry id="format">
1785         <indexterm>
1786          <primary>format</primary>
1787         </indexterm>
1788         <literal><function>format</function>(<parameter>formatstr</parameter> <type>text</type>
1789         [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ])</literal>
1790        </entry>
1791        <entry><type>text</type></entry>
1792        <entry>
1793          Format arguments according to a format string.
1794          This function is similar to the C function <function>sprintf</>.
1795          See <xref linkend="functions-string-format">.
1796        </entry>
1797        <entry><literal>format('Hello %s, %1$s', 'World')</literal></entry>
1798        <entry><literal>Hello World, World</literal></entry>
1799       </row>
1800
1801       <row>
1802        <entry>
1803         <indexterm>
1804          <primary>initcap</primary>
1805         </indexterm>
1806         <literal><function>initcap(<parameter>string</parameter>)</function></literal>
1807        </entry>
1808        <entry><type>text</type></entry>
1809        <entry>
1810         Convert the first letter of each word to upper case and the
1811         rest to lower case. Words are sequences of alphanumeric
1812         characters separated by non-alphanumeric characters.
1813        </entry>
1814        <entry><literal>initcap('hi THOMAS')</literal></entry>
1815        <entry><literal>Hi Thomas</literal></entry>
1816       </row>
1817
1818       <row>
1819        <entry>
1820         <indexterm>
1821          <primary>left</primary>
1822         </indexterm>
1823         <literal><function>left(<parameter>str</parameter> <type>text</type>,
1824         <parameter>n</parameter> <type>int</type>)</function></literal>
1825        </entry>
1826        <entry><type>text</type></entry>
1827        <entry>
1828         Return first <replaceable>n</> characters in the string. When <replaceable>n</>
1829         is negative, return all but last |<replaceable>n</>| characters.
1830         </entry>
1831        <entry><literal>left('abcde', 2)</literal></entry>
1832        <entry><literal>ab</literal></entry>
1833       </row>
1834
1835       <row>
1836        <entry>
1837         <indexterm>
1838          <primary>length</primary>
1839         </indexterm>
1840         <literal><function>length(<parameter>string</parameter>)</function></literal>
1841        </entry>
1842        <entry><type>int</type></entry>
1843        <entry>
1844         Number of characters in <parameter>string</parameter>
1845        </entry>
1846        <entry><literal>length('jose')</literal></entry>
1847        <entry><literal>4</literal></entry>
1848       </row>
1849
1850       <row>
1851        <entry><literal><function>length(<parameter>string</parameter> <type>bytea</type>,
1852         <parameter>encoding</parameter> <type>name</type> )</function></literal></entry>
1853        <entry><type>int</type></entry>
1854        <entry>
1855         Number of characters in <parameter>string</parameter> in the given
1856         <parameter>encoding</parameter>. The <parameter>string</parameter>
1857         must be valid in this encoding.
1858        </entry>
1859        <entry><literal>length('jose', 'UTF8')</literal></entry>
1860        <entry><literal>4</literal></entry>
1861       </row>
1862
1863       <row>
1864        <entry>
1865         <indexterm>
1866          <primary>lpad</primary>
1867         </indexterm>
1868         <literal><function>lpad(<parameter>string</parameter> <type>text</type>,
1869         <parameter>length</parameter> <type>int</type>
1870         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
1871        </entry>
1872        <entry><type>text</type></entry>
1873        <entry>
1874         Fill up the <parameter>string</parameter> to length
1875         <parameter>length</parameter> by prepending the characters
1876         <parameter>fill</parameter> (a space by default).  If the
1877         <parameter>string</parameter> is already longer than
1878         <parameter>length</parameter> then it is truncated (on the
1879         right).
1880        </entry>
1881        <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1882        <entry><literal>xyxhi</literal></entry>
1883       </row>
1884
1885       <row>
1886        <entry>
1887         <indexterm>
1888          <primary>ltrim</primary>
1889         </indexterm>
1890         <literal><function>ltrim(<parameter>string</parameter> <type>text</type>
1891         <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
1892        </entry>
1893        <entry><type>text</type></entry>
1894        <entry>
1895         Remove the longest string containing only characters from
1896         <parameter>characters</parameter> (a space by default) from the start of
1897         <parameter>string</parameter>
1898        </entry>
1899        <entry><literal>ltrim('zzzytest', 'xyz')</literal></entry>
1900        <entry><literal>test</literal></entry>
1901       </row>
1902
1903       <row>
1904        <entry>
1905         <indexterm>
1906          <primary>md5</primary>
1907         </indexterm>
1908         <literal><function>md5(<parameter>string</parameter>)</function></literal>
1909        </entry>
1910        <entry><type>text</type></entry>
1911        <entry>
1912         Calculates the MD5 hash of <parameter>string</parameter>,
1913         returning the result in hexadecimal
1914        </entry>
1915        <entry><literal>md5('abc')</literal></entry>
1916        <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1917       </row>
1918
1919       <row>
1920        <entry>
1921         <indexterm>
1922          <primary>parse_ident</primary>
1923         </indexterm>
1924         <literal><function>parse_ident(<parameter>qualified_identifier</parameter> <type>text</type>
1925            [, <parameter>strictmode</parameter> <type>boolean</type> DEFAULT true ] )</function></literal>
1926        </entry>
1927        <entry><type>text[]</type></entry>
1928        <entry>
1929         Split <parameter>qualified_identifier</parameter> into an array of
1930         identifiers, removing any quoting of individual identifiers.  By
1931         default, extra characters after the last identifier are considered an
1932         error; but if the second parameter is <literal>false</>, then such
1933         extra characters are ignored. (This behavior is useful for parsing
1934         names for objects like functions.) Note that this function does not
1935         truncate over-length identifiers. If you want truncation you can cast
1936         the result to <type>name[]</>.
1937        </entry>
1938        <entry><literal>parse_ident('"SomeSchema".someTable')</literal></entry>
1939        <entry><literal>{SomeSchema,sometable}</literal></entry>
1940       </row>
1941
1942       <row>
1943        <entry>
1944         <indexterm>
1945          <primary>pg_client_encoding</primary>
1946         </indexterm>
1947         <literal><function>pg_client_encoding()</function></literal>
1948        </entry>
1949        <entry><type>name</type></entry>
1950        <entry>
1951         Current client encoding name
1952        </entry>
1953        <entry><literal>pg_client_encoding()</literal></entry>
1954        <entry><literal>SQL_ASCII</literal></entry>
1955       </row>
1956
1957       <row>
1958        <entry>
1959         <indexterm>
1960          <primary>quote_ident</primary>
1961         </indexterm>
1962         <literal><function>quote_ident(<parameter>string</parameter> <type>text</type>)</function></literal>
1963        </entry>
1964        <entry><type>text</type></entry>
1965        <entry>
1966         Return the given string suitably quoted to be used as an identifier
1967         in an <acronym>SQL</acronym> statement string.
1968         Quotes are added only if necessary (i.e., if the string contains
1969         non-identifier characters or would be case-folded).
1970         Embedded quotes are properly doubled.
1971         See also <xref linkend="plpgsql-quote-literal-example">.
1972        </entry>
1973        <entry><literal>quote_ident('Foo bar')</literal></entry>
1974        <entry><literal>"Foo bar"</literal></entry>
1975       </row>
1976
1977       <row>
1978        <entry>
1979         <indexterm>
1980          <primary>quote_literal</primary>
1981         </indexterm>
1982         <literal><function>quote_literal(<parameter>string</parameter> <type>text</type>)</function></literal>
1983        </entry>
1984        <entry><type>text</type></entry>
1985        <entry>
1986         Return the given string suitably quoted to be used as a string literal
1987         in an <acronym>SQL</acronym> statement string.
1988         Embedded single-quotes and backslashes are properly doubled.
1989         Note that <function>quote_literal</function> returns null on null
1990         input; if the argument might be null,
1991         <function>quote_nullable</function> is often more suitable.
1992         See also <xref linkend="plpgsql-quote-literal-example">.
1993        </entry>
1994        <entry><literal>quote_literal(E'O\'Reilly')</literal></entry>
1995        <entry><literal>'O''Reilly'</literal></entry>
1996       </row>
1997
1998       <row>
1999        <entry><literal><function>quote_literal(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
2000        <entry><type>text</type></entry>
2001        <entry>
2002         Coerce the given value to text and then quote it as a literal.
2003         Embedded single-quotes and backslashes are properly doubled.
2004        </entry>
2005        <entry><literal>quote_literal(42.5)</literal></entry>
2006        <entry><literal>'42.5'</literal></entry>
2007       </row>
2008
2009       <row>
2010        <entry>
2011         <indexterm>
2012          <primary>quote_nullable</primary>
2013         </indexterm>
2014         <literal><function>quote_nullable(<parameter>string</parameter> <type>text</type>)</function></literal>
2015        </entry>
2016        <entry><type>text</type></entry>
2017        <entry>
2018         Return the given string suitably quoted to be used as a string literal
2019         in an <acronym>SQL</acronym> statement string; or, if the argument
2020         is null, return <literal>NULL</>.
2021         Embedded single-quotes and backslashes are properly doubled.
2022         See also <xref linkend="plpgsql-quote-literal-example">.
2023        </entry>
2024        <entry><literal>quote_nullable(NULL)</literal></entry>
2025        <entry><literal>NULL</literal></entry>
2026       </row>
2027
2028       <row>
2029        <entry><literal><function>quote_nullable(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
2030        <entry><type>text</type></entry>
2031        <entry>
2032         Coerce the given value to text and then quote it as a literal;
2033         or, if the argument is null, return <literal>NULL</>.
2034         Embedded single-quotes and backslashes are properly doubled.
2035        </entry>
2036        <entry><literal>quote_nullable(42.5)</literal></entry>
2037        <entry><literal>'42.5'</literal></entry>
2038       </row>
2039
2040       <row>
2041        <entry>
2042         <indexterm>
2043          <primary>regexp_match</primary>
2044         </indexterm>
2045         <literal><function>regexp_match(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
2046        </entry>
2047        <entry><type>text[]</type></entry>
2048        <entry>
2049         Return captured substring(s) resulting from the first match of a POSIX
2050         regular expression to the <parameter>string</parameter>. See
2051         <xref linkend="functions-posix-regexp"> for more information.
2052        </entry>
2053        <entry><literal>regexp_match('foobarbequebaz', '(bar)(beque)')</literal></entry>
2054        <entry><literal>{bar,beque}</literal></entry>
2055       </row>
2056
2057       <row>
2058        <entry>
2059         <indexterm>
2060          <primary>regexp_matches</primary>
2061         </indexterm>
2062         <literal><function>regexp_matches(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
2063        </entry>
2064        <entry><type>setof text[]</type></entry>
2065        <entry>
2066         Return captured substring(s) resulting from matching a POSIX regular
2067         expression to the <parameter>string</parameter>. See
2068         <xref linkend="functions-posix-regexp"> for more information.
2069        </entry>
2070        <entry><literal>regexp_matches('foobarbequebaz', 'ba.', 'g')</literal></entry>
2071        <entry><literal>{bar}</literal><para><literal>{baz}</literal></para> (2 rows)</entry>
2072       </row>
2073
2074       <row>
2075        <entry>
2076         <indexterm>
2077          <primary>regexp_replace</primary>
2078         </indexterm>
2079         <literal><function>regexp_replace(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
2080        </entry>
2081        <entry><type>text</type></entry>
2082        <entry>
2083         Replace substring(s) matching a POSIX regular expression. See
2084         <xref linkend="functions-posix-regexp"> for more information.
2085        </entry>
2086        <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
2087        <entry><literal>ThM</literal></entry>
2088       </row>
2089
2090       <row>
2091        <entry>
2092         <indexterm>
2093          <primary>regexp_split_to_array</primary>
2094         </indexterm>
2095         <literal><function>regexp_split_to_array(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ])</function></literal>
2096        </entry>
2097        <entry><type>text[]</type></entry>
2098        <entry>
2099         Split <parameter>string</parameter> using a POSIX regular expression as
2100         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
2101         information.
2102        </entry>
2103        <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
2104        <entry><literal>{hello,world}</literal></entry>
2105       </row>
2106
2107       <row>
2108        <entry>
2109         <indexterm>
2110          <primary>regexp_split_to_table</primary>
2111         </indexterm>
2112         <literal><function>regexp_split_to_table(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
2113        </entry>
2114        <entry><type>setof text</type></entry>
2115        <entry>
2116         Split <parameter>string</parameter> using a POSIX regular expression as
2117         the delimiter.  See <xref linkend="functions-posix-regexp"> for more
2118         information.
2119        </entry>
2120        <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
2121        <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
2122       </row>
2123
2124       <row>
2125        <entry>
2126         <indexterm>
2127          <primary>repeat</primary>
2128         </indexterm>
2129         <literal><function>repeat(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</function></literal>
2130        </entry>
2131        <entry><type>text</type></entry>
2132        <entry>Repeat <parameter>string</parameter> the specified
2133        <parameter>number</parameter> of times</entry>
2134        <entry><literal>repeat('Pg', 4)</literal></entry>
2135        <entry><literal>PgPgPgPg</literal></entry>
2136       </row>
2137
2138       <row>
2139        <entry>
2140         <indexterm>
2141          <primary>replace</primary>
2142         </indexterm>
2143         <literal><function>replace(<parameter>string</parameter> <type>text</type>,
2144         <parameter>from</parameter> <type>text</type>,
2145         <parameter>to</parameter> <type>text</type>)</function></literal>
2146        </entry>
2147        <entry><type>text</type></entry>
2148        <entry>Replace all occurrences in <parameter>string</parameter> of substring
2149         <parameter>from</parameter> with substring <parameter>to</parameter>
2150        </entry>
2151        <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
2152        <entry><literal>abXXefabXXef</literal></entry>
2153       </row>
2154
2155       <row>
2156        <entry>
2157         <indexterm>
2158          <primary>reverse</primary>
2159         </indexterm>
2160         <literal><function>reverse(<parameter>str</parameter>)</function></literal>
2161        </entry>
2162        <entry><type>text</type></entry>
2163        <entry>
2164         Return reversed string.
2165        </entry>
2166        <entry><literal>reverse('abcde')</literal></entry>
2167        <entry><literal>edcba</literal></entry>
2168       </row>
2169
2170       <row>
2171        <entry>
2172         <indexterm>
2173          <primary>right</primary>
2174         </indexterm>
2175         <literal><function>right(<parameter>str</parameter> <type>text</type>,
2176          <parameter>n</parameter> <type>int</type>)</function></literal>
2177        </entry>
2178        <entry><type>text</type></entry>
2179        <entry>
2180         Return last <replaceable>n</> characters in the string. When <replaceable>n</>
2181         is negative, return all but first |<replaceable>n</>| characters.
2182        </entry>
2183        <entry><literal>right('abcde', 2)</literal></entry>
2184        <entry><literal>de</literal></entry>
2185       </row>
2186
2187       <row>
2188        <entry>
2189         <indexterm>
2190          <primary>rpad</primary>
2191         </indexterm>
2192         <literal><function>rpad(<parameter>string</parameter> <type>text</type>,
2193         <parameter>length</parameter> <type>int</type>
2194         <optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
2195        </entry>
2196        <entry><type>text</type></entry>
2197        <entry>
2198         Fill up the <parameter>string</parameter> to length
2199         <parameter>length</parameter> by appending the characters
2200         <parameter>fill</parameter> (a space by default).  If the
2201         <parameter>string</parameter> is already longer than
2202         <parameter>length</parameter> then it is truncated.
2203        </entry>
2204        <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
2205        <entry><literal>hixyx</literal></entry>
2206       </row>
2207
2208       <row>
2209        <entry>
2210         <indexterm>
2211          <primary>rtrim</primary>
2212         </indexterm>
2213         <literal><function>rtrim(<parameter>string</parameter> <type>text</type>
2214          <optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
2215        </entry>
2216        <entry><type>text</type></entry>
2217        <entry>
2218         Remove the longest string containing only characters from
2219         <parameter>characters</parameter> (a space by default) from the end of
2220         <parameter>string</parameter>
2221        </entry>
2222        <entry><literal>rtrim('testxxzx', 'xyz')</literal></entry>
2223        <entry><literal>test</literal></entry>
2224       </row>
2225
2226       <row>
2227        <entry>
2228         <indexterm>
2229          <primary>split_part</primary>
2230         </indexterm>
2231         <literal><function>split_part(<parameter>string</parameter> <type>text</type>,
2232         <parameter>delimiter</parameter> <type>text</type>,
2233         <parameter>field</parameter> <type>int</type>)</function></literal>
2234        </entry>
2235        <entry><type>text</type></entry>
2236        <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
2237         and return the given field (counting from one)
2238        </entry>
2239        <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
2240        <entry><literal>def</literal></entry>
2241       </row>
2242
2243       <row>
2244        <entry>
2245         <indexterm>
2246          <primary>strpos</primary>
2247         </indexterm>
2248         <literal><function>strpos(<parameter>string</parameter>, <parameter>substring</parameter>)</function></literal>
2249        </entry>
2250        <entry><type>int</type></entry>
2251        <entry>
2252         Location of specified substring (same as
2253         <literal>position(<parameter>substring</parameter> in
2254          <parameter>string</parameter>)</literal>, but note the reversed
2255         argument order)
2256        </entry>
2257        <entry><literal>strpos('high', 'ig')</literal></entry>
2258        <entry><literal>2</literal></entry>
2259       </row>
2260
2261       <row>
2262        <entry>
2263         <indexterm>
2264          <primary>substr</primary>
2265         </indexterm>
2266         <literal><function>substr(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</function></literal>
2267        </entry>
2268        <entry><type>text</type></entry>
2269        <entry>
2270         Extract substring (same as
2271         <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
2272        </entry>
2273        <entry><literal>substr('alphabet', 3, 2)</literal></entry>
2274        <entry><literal>ph</literal></entry>
2275       </row>
2276
2277       <row>
2278        <entry>
2279         <indexterm>
2280          <primary>to_ascii</primary>
2281         </indexterm>
2282         <literal><function>to_ascii(<parameter>string</parameter> <type>text</type>
2283         <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</function></literal>
2284        </entry>
2285        <entry><type>text</type></entry>
2286        <entry>
2287        Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
2288        (only supports conversion from  <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
2289        and <literal>WIN1250</> encodings)
2290        </entry>
2291        <entry><literal>to_ascii('Karel')</literal></entry>
2292        <entry><literal>Karel</literal></entry>
2293       </row>
2294
2295       <row>
2296        <entry>
2297         <indexterm>
2298          <primary>to_hex</primary>
2299         </indexterm>
2300         <literal><function>to_hex(<parameter>number</parameter> <type>int</type>
2301         or <type>bigint</type>)</function></literal>
2302        </entry>
2303        <entry><type>text</type></entry>
2304        <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
2305         representation
2306        </entry>
2307        <entry><literal>to_hex(2147483647)</literal></entry>
2308        <entry><literal>7fffffff</literal></entry>
2309       </row>
2310
2311       <row>
2312        <entry>
2313         <indexterm>
2314          <primary>translate</primary>
2315         </indexterm>
2316         <literal><function>translate(<parameter>string</parameter> <type>text</type>,
2317         <parameter>from</parameter> <type>text</type>,
2318         <parameter>to</parameter> <type>text</type>)</function></literal>
2319        </entry>
2320        <entry><type>text</type></entry>
2321        <entry>
2322         Any character in <parameter>string</parameter> that matches a
2323         character in the <parameter>from</parameter> set is replaced by
2324         the corresponding character in the <parameter>to</parameter>
2325         set. If <parameter>from</parameter> is longer than
2326         <parameter>to</parameter>, occurrences of the extra characters in
2327         <parameter>from</parameter> are removed.
2328        </entry>
2329        <entry><literal>translate('12345', '143', 'ax')</literal></entry>
2330        <entry><literal>a2x5</literal></entry>
2331       </row>
2332
2333      </tbody>
2334     </tgroup>
2335    </table>
2336
2337    <para>
2338     The <function>concat</function>, <function>concat_ws</function> and
2339     <function>format</function> functions are variadic, so it is possible to
2340     pass the values to be concatenated or formatted as an array marked with
2341     the <literal>VARIADIC</literal> keyword (see <xref
2342     linkend="xfunc-sql-variadic-functions">).  The array's elements are
2343     treated as if they were separate ordinary arguments to the function.
2344     If the variadic array argument is NULL, <function>concat</function>
2345     and <function>concat_ws</function> return NULL, but
2346     <function>format</function> treats a NULL as a zero-element array.
2347    </para>
2348
2349    <para>
2350    See also the aggregate function <function>string_agg</function> in
2351    <xref linkend="functions-aggregate">.
2352    </para>
2353
2354    <table id="conversion-names">
2355     <title>Built-in Conversions</title>
2356     <tgroup cols="3">
2357      <thead>
2358       <row>
2359        <entry>Conversion Name
2360         <footnote>
2361          <para>
2362           The conversion names follow a standard naming scheme: The
2363           official name of the source encoding with all
2364           non-alphanumeric characters replaced by underscores, followed
2365           by <literal>_to_</literal>, followed by the similarly processed
2366           destination encoding name. Therefore, the names might deviate
2367           from the customary encoding names.
2368          </para>
2369         </footnote>
2370        </entry>
2371        <entry>Source Encoding</entry>
2372        <entry>Destination Encoding</entry>
2373       </row>
2374      </thead>
2375
2376      <tbody>
2377       <row>
2378        <entry><literal>ascii_to_mic</literal></entry>
2379        <entry><literal>SQL_ASCII</literal></entry>
2380        <entry><literal>MULE_INTERNAL</literal></entry>
2381       </row>
2382
2383       <row>
2384        <entry><literal>ascii_to_utf8</literal></entry>
2385        <entry><literal>SQL_ASCII</literal></entry>
2386        <entry><literal>UTF8</literal></entry>
2387       </row>
2388
2389       <row>
2390        <entry><literal>big5_to_euc_tw</literal></entry>
2391        <entry><literal>BIG5</literal></entry>
2392        <entry><literal>EUC_TW</literal></entry>
2393       </row>
2394
2395       <row>
2396        <entry><literal>big5_to_mic</literal></entry>
2397        <entry><literal>BIG5</literal></entry>
2398        <entry><literal>MULE_INTERNAL</literal></entry>
2399       </row>
2400
2401       <row>
2402        <entry><literal>big5_to_utf8</literal></entry>
2403        <entry><literal>BIG5</literal></entry>
2404        <entry><literal>UTF8</literal></entry>
2405       </row>
2406
2407       <row>
2408        <entry><literal>euc_cn_to_mic</literal></entry>
2409        <entry><literal>EUC_CN</literal></entry>
2410        <entry><literal>MULE_INTERNAL</literal></entry>
2411       </row>
2412
2413       <row>
2414        <entry><literal>euc_cn_to_utf8</literal></entry>
2415        <entry><literal>EUC_CN</literal></entry>
2416        <entry><literal>UTF8</literal></entry>
2417       </row>
2418
2419       <row>
2420        <entry><literal>euc_jp_to_mic</literal></entry>
2421        <entry><literal>EUC_JP</literal></entry>
2422        <entry><literal>MULE_INTERNAL</literal></entry>
2423       </row>
2424
2425       <row>
2426        <entry><literal>euc_jp_to_sjis</literal></entry>
2427        <entry><literal>EUC_JP</literal></entry>
2428        <entry><literal>SJIS</literal></entry>
2429       </row>
2430
2431       <row>
2432        <entry><literal>euc_jp_to_utf8</literal></entry>
2433        <entry><literal>EUC_JP</literal></entry>
2434        <entry><literal>UTF8</literal></entry>
2435       </row>
2436
2437       <row>
2438        <entry><literal>euc_kr_to_mic</literal></entry>
2439        <entry><literal>EUC_KR</literal></entry>
2440        <entry><literal>MULE_INTERNAL</literal></entry>
2441       </row>
2442
2443       <row>
2444        <entry><literal>euc_kr_to_utf8</literal></entry>
2445        <entry><literal>EUC_KR</literal></entry>
2446        <entry><literal>UTF8</literal></entry>
2447       </row>
2448
2449       <row>
2450        <entry><literal>euc_tw_to_big5</literal></entry>
2451        <entry><literal>EUC_TW</literal></entry>
2452        <entry><literal>BIG5</literal></entry>
2453       </row>
2454
2455       <row>
2456        <entry><literal>euc_tw_to_mic</literal></entry>
2457        <entry><literal>EUC_TW</literal></entry>
2458        <entry><literal>MULE_INTERNAL</literal></entry>
2459       </row>
2460
2461       <row>
2462        <entry><literal>euc_tw_to_utf8</literal></entry>
2463        <entry><literal>EUC_TW</literal></entry>
2464        <entry><literal>UTF8</literal></entry>
2465       </row>
2466
2467       <row>
2468        <entry><literal>gb18030_to_utf8</literal></entry>
2469        <entry><literal>GB18030</literal></entry>
2470        <entry><literal>UTF8</literal></entry>
2471       </row>
2472
2473       <row>
2474        <entry><literal>gbk_to_utf8</literal></entry>
2475        <entry><literal>GBK</literal></entry>
2476        <entry><literal>UTF8</literal></entry>
2477       </row>
2478
2479       <row>
2480        <entry><literal>iso_8859_10_to_utf8</literal></entry>
2481        <entry><literal>LATIN6</literal></entry>
2482        <entry><literal>UTF8</literal></entry>
2483       </row>
2484
2485       <row>
2486        <entry><literal>iso_8859_13_to_utf8</literal></entry>
2487        <entry><literal>LATIN7</literal></entry>
2488        <entry><literal>UTF8</literal></entry>
2489       </row>
2490
2491       <row>
2492        <entry><literal>iso_8859_14_to_utf8</literal></entry>
2493        <entry><literal>LATIN8</literal></entry>
2494        <entry><literal>UTF8</literal></entry>
2495       </row>
2496
2497       <row>
2498        <entry><literal>iso_8859_15_to_utf8</literal></entry>
2499        <entry><literal>LATIN9</literal></entry>
2500        <entry><literal>UTF8</literal></entry>
2501       </row>
2502
2503       <row>
2504        <entry><literal>iso_8859_16_to_utf8</literal></entry>
2505        <entry><literal>LATIN10</literal></entry>
2506        <entry><literal>UTF8</literal></entry>
2507       </row>
2508
2509       <row>
2510        <entry><literal>iso_8859_1_to_mic</literal></entry>
2511        <entry><literal>LATIN1</literal></entry>
2512        <entry><literal>MULE_INTERNAL</literal></entry>
2513       </row>
2514
2515       <row>
2516        <entry><literal>iso_8859_1_to_utf8</literal></entry>
2517        <entry><literal>LATIN1</literal></entry>
2518        <entry><literal>UTF8</literal></entry>
2519       </row>
2520
2521       <row>
2522        <entry><literal>iso_8859_2_to_mic</literal></entry>
2523        <entry><literal>LATIN2</literal></entry>
2524        <entry><literal>MULE_INTERNAL</literal></entry>
2525       </row>
2526
2527       <row>
2528        <entry><literal>iso_8859_2_to_utf8</literal></entry>
2529        <entry><literal>LATIN2</literal></entry>
2530        <entry><literal>UTF8</literal></entry>
2531       </row>
2532
2533       <row>
2534        <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
2535        <entry><literal>LATIN2</literal></entry>
2536        <entry><literal>WIN1250</literal></entry>
2537       </row>
2538
2539       <row>
2540        <entry><literal>iso_8859_3_to_mic</literal></entry>
2541        <entry><literal>LATIN3</literal></entry>
2542        <entry><literal>MULE_INTERNAL</literal></entry>
2543       </row>
2544
2545       <row>
2546        <entry><literal>iso_8859_3_to_utf8</literal></entry>
2547        <entry><literal>LATIN3</literal></entry>
2548        <entry><literal>UTF8</literal></entry>
2549       </row>
2550
2551       <row>
2552        <entry><literal>iso_8859_4_to_mic</literal></entry>
2553        <entry><literal>LATIN4</literal></entry>
2554        <entry><literal>MULE_INTERNAL</literal></entry>
2555       </row>
2556
2557       <row>
2558        <entry><literal>iso_8859_4_to_utf8</literal></entry>
2559        <entry><literal>LATIN4</literal></entry>
2560        <entry><literal>UTF8</literal></entry>
2561       </row>
2562
2563       <row>
2564        <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
2565        <entry><literal>ISO_8859_5</literal></entry>
2566        <entry><literal>KOI8R</literal></entry>
2567       </row>
2568
2569       <row>
2570        <entry><literal>iso_8859_5_to_mic</literal></entry>
2571        <entry><literal>ISO_8859_5</literal></entry>
2572        <entry><literal>MULE_INTERNAL</literal></entry>
2573       </row>
2574
2575       <row>
2576        <entry><literal>iso_8859_5_to_utf8</literal></entry>
2577        <entry><literal>ISO_8859_5</literal></entry>
2578        <entry><literal>UTF8</literal></entry>
2579       </row>
2580
2581       <row>
2582        <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
2583        <entry><literal>ISO_8859_5</literal></entry>
2584        <entry><literal>WIN1251</literal></entry>
2585       </row>
2586
2587       <row>
2588        <entry><literal>iso_8859_5_to_windows_866</literal></entry>
2589        <entry><literal>ISO_8859_5</literal></entry>
2590        <entry><literal>WIN866</literal></entry>
2591       </row>
2592
2593       <row>
2594        <entry><literal>iso_8859_6_to_utf8</literal></entry>
2595        <entry><literal>ISO_8859_6</literal></entry>
2596        <entry><literal>UTF8</literal></entry>
2597       </row>
2598
2599       <row>
2600        <entry><literal>iso_8859_7_to_utf8</literal></entry>
2601        <entry><literal>ISO_8859_7</literal></entry>
2602        <entry><literal>UTF8</literal></entry>
2603       </row>
2604
2605       <row>
2606        <entry><literal>iso_8859_8_to_utf8</literal></entry>
2607        <entry><literal>ISO_8859_8</literal></entry>
2608        <entry><literal>UTF8</literal></entry>
2609       </row>
2610
2611       <row>
2612        <entry><literal>iso_8859_9_to_utf8</literal></entry>
2613        <entry><literal>LATIN5</literal></entry>
2614        <entry><literal>UTF8</literal></entry>
2615       </row>
2616
2617       <row>
2618        <entry><literal>johab_to_utf8</literal></entry>
2619        <entry><literal>JOHAB</literal></entry>
2620        <entry><literal>UTF8</literal></entry>
2621       </row>
2622
2623       <row>
2624        <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
2625        <entry><literal>KOI8R</literal></entry>
2626        <entry><literal>ISO_8859_5</literal></entry>
2627       </row>
2628
2629       <row>
2630        <entry><literal>koi8_r_to_mic</literal></entry>
2631        <entry><literal>KOI8R</literal></entry>
2632        <entry><literal>MULE_INTERNAL</literal></entry>
2633       </row>
2634
2635       <row>
2636        <entry><literal>koi8_r_to_utf8</literal></entry>
2637        <entry><literal>KOI8R</literal></entry>
2638        <entry><literal>UTF8</literal></entry>
2639       </row>
2640
2641       <row>
2642        <entry><literal>koi8_r_to_windows_1251</literal></entry>
2643        <entry><literal>KOI8R</literal></entry>
2644        <entry><literal>WIN1251</literal></entry>
2645       </row>
2646
2647       <row>
2648        <entry><literal>koi8_r_to_windows_866</literal></entry>
2649        <entry><literal>KOI8R</literal></entry>
2650        <entry><literal>WIN866</literal></entry>
2651       </row>
2652
2653       <row>
2654        <entry><literal>koi8_u_to_utf8</literal></entry>
2655        <entry><literal>KOI8U</literal></entry>
2656        <entry><literal>UTF8</literal></entry>
2657       </row>
2658
2659       <row>
2660        <entry><literal>mic_to_ascii</literal></entry>
2661        <entry><literal>MULE_INTERNAL</literal></entry>
2662        <entry><literal>SQL_ASCII</literal></entry>
2663       </row>
2664
2665       <row>
2666        <entry><literal>mic_to_big5</literal></entry>
2667        <entry><literal>MULE_INTERNAL</literal></entry>
2668        <entry><literal>BIG5</literal></entry>
2669       </row>
2670
2671       <row>
2672        <entry><literal>mic_to_euc_cn</literal></entry>
2673        <entry><literal>MULE_INTERNAL</literal></entry>
2674        <entry><literal>EUC_CN</literal></entry>
2675       </row>
2676
2677       <row>
2678        <entry><literal>mic_to_euc_jp</literal></entry>
2679        <entry><literal>MULE_INTERNAL</literal></entry>
2680        <entry><literal>EUC_JP</literal></entry>
2681       </row>
2682
2683       <row>
2684        <entry><literal>mic_to_euc_kr</literal></entry>
2685        <entry><literal>MULE_INTERNAL</literal></entry>
2686        <entry><literal>EUC_KR</literal></entry>
2687       </row>
2688
2689       <row>
2690        <entry><literal>mic_to_euc_tw</literal></entry>
2691        <entry><literal>MULE_INTERNAL</literal></entry>
2692        <entry><literal>EUC_TW</literal></entry>
2693       </row>
2694
2695       <row>
2696        <entry><literal>mic_to_iso_8859_1</literal></entry>
2697        <entry><literal>MULE_INTERNAL</literal></entry>
2698        <entry><literal>LATIN1</literal></entry>
2699       </row>
2700
2701       <row>
2702        <entry><literal>mic_to_iso_8859_2</literal></entry>
2703        <entry><literal>MULE_INTERNAL</literal></entry>
2704        <entry><literal>LATIN2</literal></entry>
2705       </row>
2706
2707       <row>
2708        <entry><literal>mic_to_iso_8859_3</literal></entry>
2709        <entry><literal>MULE_INTERNAL</literal></entry>
2710        <entry><literal>LATIN3</literal></entry>
2711       </row>
2712
2713       <row>
2714        <entry><literal>mic_to_iso_8859_4</literal></entry>
2715        <entry><literal>MULE_INTERNAL</literal></entry>
2716        <entry><literal>LATIN4</literal></entry>
2717       </row>
2718
2719       <row>
2720        <entry><literal>mic_to_iso_8859_5</literal></entry>
2721        <entry><literal>MULE_INTERNAL</literal></entry>
2722        <entry><literal>ISO_8859_5</literal></entry>
2723       </row>
2724
2725       <row>
2726        <entry><literal>mic_to_koi8_r</literal></entry>
2727        <entry><literal>MULE_INTERNAL</literal></entry>
2728        <entry><literal>KOI8R</literal></entry>
2729       </row>
2730
2731       <row>
2732        <entry><literal>mic_to_sjis</literal></entry>
2733        <entry><literal>MULE_INTERNAL</literal></entry>
2734        <entry><literal>SJIS</literal></entry>
2735       </row>
2736
2737       <row>
2738        <entry><literal>mic_to_windows_1250</literal></entry>
2739        <entry><literal>MULE_INTERNAL</literal></entry>
2740        <entry><literal>WIN1250</literal></entry>
2741       </row>
2742
2743       <row>
2744        <entry><literal>mic_to_windows_1251</literal></entry>
2745        <entry><literal>MULE_INTERNAL</literal></entry>
2746        <entry><literal>WIN1251</literal></entry>
2747       </row>
2748
2749       <row>
2750        <entry><literal>mic_to_windows_866</literal></entry>
2751        <entry><literal>MULE_INTERNAL</literal></entry>
2752        <entry><literal>WIN866</literal></entry>
2753       </row>
2754
2755       <row>
2756        <entry><literal>sjis_to_euc_jp</literal></entry>
2757        <entry><literal>SJIS</literal></entry>
2758        <entry><literal>EUC_JP</literal></entry>
2759       </row>
2760
2761       <row>
2762        <entry><literal>sjis_to_mic</literal></entry>
2763        <entry><literal>SJIS</literal></entry>
2764        <entry><literal>MULE_INTERNAL</literal></entry>
2765       </row>
2766
2767       <row>
2768        <entry><literal>sjis_to_utf8</literal></entry>
2769        <entry><literal>SJIS</literal></entry>
2770        <entry><literal>UTF8</literal></entry>
2771       </row>
2772
2773       <row>
2774        <entry><literal>tcvn_to_utf8</literal></entry>
2775        <entry><literal>WIN1258</literal></entry>
2776        <entry><literal>UTF8</literal></entry>
2777       </row>
2778
2779       <row>
2780        <entry><literal>uhc_to_utf8</literal></entry>
2781        <entry><literal>UHC</literal></entry>
2782        <entry><literal>UTF8</literal></entry>
2783       </row>
2784
2785       <row>
2786        <entry><literal>utf8_to_ascii</literal></entry>
2787        <entry><literal>UTF8</literal></entry>
2788        <entry><literal>SQL_ASCII</literal></entry>
2789       </row>
2790
2791       <row>
2792        <entry><literal>utf8_to_big5</literal></entry>
2793        <entry><literal>UTF8</literal></entry>
2794        <entry><literal>BIG5</literal></entry>
2795       </row>
2796
2797       <row>
2798        <entry><literal>utf8_to_euc_cn</literal></entry>
2799        <entry><literal>UTF8</literal></entry>
2800        <entry><literal>EUC_CN</literal></entry>
2801       </row>
2802
2803       <row>
2804        <entry><literal>utf8_to_euc_jp</literal></entry>
2805        <entry><literal>UTF8</literal></entry>
2806        <entry><literal>EUC_JP</literal></entry>
2807       </row>
2808
2809       <row>
2810        <entry><literal>utf8_to_euc_kr</literal></entry>
2811        <entry><literal>UTF8</literal></entry>
2812        <entry><literal>EUC_KR</literal></entry>
2813       </row>
2814
2815       <row>
2816        <entry><literal>utf8_to_euc_tw</literal></entry>
2817        <entry><literal>UTF8</literal></entry>
2818        <entry><literal>EUC_TW</literal></entry>
2819       </row>
2820
2821       <row>
2822        <entry><literal>utf8_to_gb18030</literal></entry>
2823        <entry><literal>UTF8</literal></entry>
2824        <entry><literal>GB18030</literal></entry>
2825       </row>
2826
2827       <row>
2828        <entry><literal>utf8_to_gbk</literal></entry>
2829        <entry><literal>UTF8</literal></entry>
2830        <entry><literal>GBK</literal></entry>
2831       </row>
2832
2833       <row>
2834        <entry><literal>utf8_to_iso_8859_1</literal></entry>
2835        <entry><literal>UTF8</literal></entry>
2836        <entry><literal>LATIN1</literal></entry>
2837       </row>
2838
2839       <row>
2840        <entry><literal>utf8_to_iso_8859_10</literal></entry>
2841        <entry><literal>UTF8</literal></entry>
2842        <entry><literal>LATIN6</literal></entry>
2843       </row>
2844
2845       <row>
2846        <entry><literal>utf8_to_iso_8859_13</literal></entry>
2847        <entry><literal>UTF8</literal></entry>
2848        <entry><literal>LATIN7</literal></entry>
2849       </row>
2850
2851       <row>
2852        <entry><literal>utf8_to_iso_8859_14</literal></entry>
2853        <entry><literal>UTF8</literal></entry>
2854        <entry><literal>LATIN8</literal></entry>
2855       </row>
2856
2857       <row>
2858        <entry><literal>utf8_to_iso_8859_15</literal></entry>
2859        <entry><literal>UTF8</literal></entry>
2860        <entry><literal>LATIN9</literal></entry>
2861       </row>
2862
2863       <row>
2864        <entry><literal>utf8_to_iso_8859_16</literal></entry>
2865        <entry><literal>UTF8</literal></entry>
2866        <entry><literal>LATIN10</literal></entry>
2867       </row>
2868
2869       <row>
2870        <entry><literal>utf8_to_iso_8859_2</literal></entry>
2871        <entry><literal>UTF8</literal></entry>
2872        <entry><literal>LATIN2</literal></entry>
2873       </row>
2874
2875       <row>
2876        <entry><literal>utf8_to_iso_8859_3</literal></entry>
2877        <entry><literal>UTF8</literal></entry>
2878        <entry><literal>LATIN3</literal></entry>
2879       </row>
2880
2881       <row>
2882        <entry><literal>utf8_to_iso_8859_4</literal></entry>
2883        <entry><literal>UTF8</literal></entry>
2884        <entry><literal>LATIN4</literal></entry>
2885       </row>
2886
2887       <row>
2888        <entry><literal>utf8_to_iso_8859_5</literal></entry>
2889        <entry><literal>UTF8</literal></entry>
2890        <entry><literal>ISO_8859_5</literal></entry>
2891       </row>
2892
2893       <row>
2894        <entry><literal>utf8_to_iso_8859_6</literal></entry>
2895        <entry><literal>UTF8</literal></entry>
2896        <entry><literal>ISO_8859_6</literal></entry>
2897       </row>
2898
2899       <row>
2900        <entry><literal>utf8_to_iso_8859_7</literal></entry>
2901        <entry><literal>UTF8</literal></entry>
2902        <entry><literal>ISO_8859_7</literal></entry>
2903       </row>
2904
2905       <row>
2906        <entry><literal>utf8_to_iso_8859_8</literal></entry>
2907        <entry><literal>UTF8</literal></entry>
2908        <entry><literal>ISO_8859_8</literal></entry>
2909       </row>
2910
2911       <row>
2912        <entry><literal>utf8_to_iso_8859_9</literal></entry>
2913        <entry><literal>UTF8</literal></entry>
2914        <entry><literal>LATIN5</literal></entry>
2915       </row>
2916
2917       <row>
2918        <entry><literal>utf8_to_johab</literal></entry>
2919        <entry><literal>UTF8</literal></entry>
2920        <entry><literal>JOHAB</literal></entry>
2921       </row>
2922
2923       <row>
2924        <entry><literal>utf8_to_koi8_r</literal></entry>
2925        <entry><literal>UTF8</literal></entry>
2926        <entry><literal>KOI8R</literal></entry>
2927       </row>
2928
2929       <row>
2930        <entry><literal>utf8_to_koi8_u</literal></entry>
2931        <entry><literal>UTF8</literal></entry>
2932        <entry><literal>KOI8U</literal></entry>
2933       </row>
2934
2935       <row>
2936        <entry><literal>utf8_to_sjis</literal></entry>
2937        <entry><literal>UTF8</literal></entry>
2938        <entry><literal>SJIS</literal></entry>
2939       </row>
2940
2941       <row>
2942        <entry><literal>utf8_to_tcvn</literal></entry>
2943        <entry><literal>UTF8</literal></entry>
2944        <entry><literal>WIN1258</literal></entry>
2945       </row>
2946
2947       <row>
2948        <entry><literal>utf8_to_uhc</literal></entry>
2949        <entry><literal>UTF8</literal></entry>
2950        <entry><literal>UHC</literal></entry>
2951       </row>
2952
2953       <row>
2954        <entry><literal>utf8_to_windows_1250</literal></entry>
2955        <entry><literal>UTF8</literal></entry>
2956        <entry><literal>WIN1250</literal></entry>
2957       </row>
2958
2959       <row>
2960        <entry><literal>utf8_to_windows_1251</literal></entry>
2961        <entry><literal>UTF8</literal></entry>
2962        <entry><literal>WIN1251</literal></entry>
2963       </row>
2964
2965       <row>
2966        <entry><literal>utf8_to_windows_1252</literal></entry>
2967        <entry><literal>UTF8</literal></entry>
2968        <entry><literal>WIN1252</literal></entry>
2969       </row>
2970
2971       <row>
2972        <entry><literal>utf8_to_windows_1253</literal></entry>
2973        <entry><literal>UTF8</literal></entry>
2974        <entry><literal>WIN1253</literal></entry>
2975       </row>
2976
2977       <row>
2978        <entry><literal>utf8_to_windows_1254</literal></entry>
2979        <entry><literal>UTF8</literal></entry>
2980        <entry><literal>WIN1254</literal></entry>
2981       </row>
2982
2983       <row>
2984        <entry><literal>utf8_to_windows_1255</literal></entry>
2985        <entry><literal>UTF8</literal></entry>
2986        <entry><literal>WIN1255</literal></entry>
2987       </row>
2988
2989       <row>
2990        <entry><literal>utf8_to_windows_1256</literal></entry>
2991        <entry><literal>UTF8</literal></entry>
2992        <entry><literal>WIN1256</literal></entry>
2993       </row>
2994
2995       <row>
2996        <entry><literal>utf8_to_windows_1257</literal></entry>
2997        <entry><literal>UTF8</literal></entry>
2998        <entry><literal>WIN1257</literal></entry>
2999       </row>
3000
3001       <row>
3002        <entry><literal>utf8_to_windows_866</literal></entry>
3003        <entry><literal>UTF8</literal></entry>
3004        <entry><literal>WIN866</literal></entry>
3005       </row>
3006
3007       <row>
3008        <entry><literal>utf8_to_windows_874</literal></entry>
3009        <entry><literal>UTF8</literal></entry>
3010        <entry><literal>WIN874</literal></entry>
3011       </row>
3012
3013       <row>
3014        <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
3015        <entry><literal>WIN1250</literal></entry>
3016        <entry><literal>LATIN2</literal></entry>
3017       </row>
3018
3019       <row>
3020        <entry><literal>windows_1250_to_mic</literal></entry>
3021        <entry><literal>WIN1250</literal></entry>
3022        <entry><literal>MULE_INTERNAL</literal></entry>
3023       </row>
3024
3025       <row>
3026        <entry><literal>windows_1250_to_utf8</literal></entry>
3027        <entry><literal>WIN1250</literal></entry>
3028        <entry><literal>UTF8</literal></entry>
3029       </row>
3030
3031       <row>
3032        <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
3033        <entry><literal>WIN1251</literal></entry>
3034        <entry><literal>ISO_8859_5</literal></entry>
3035       </row>
3036
3037       <row>
3038        <entry><literal>windows_1251_to_koi8_r</literal></entry>
3039        <entry><literal>WIN1251</literal></entry>
3040        <entry><literal>KOI8R</literal></entry>
3041       </row>
3042
3043       <row>
3044        <entry><literal>windows_1251_to_mic</literal></entry>
3045        <entry><literal>WIN1251</literal></entry>
3046        <entry><literal>MULE_INTERNAL</literal></entry>
3047       </row>
3048
3049       <row>
3050        <entry><literal>windows_1251_to_utf8</literal></entry>
3051        <entry><literal>WIN1251</literal></entry>
3052        <entry><literal>UTF8</literal></entry>
3053       </row>
3054
3055       <row>
3056        <entry><literal>windows_1251_to_windows_866</literal></entry>
3057        <entry><literal>WIN1251</literal></entry>
3058        <entry><literal>WIN866</literal></entry>
3059       </row>
3060
3061       <row>
3062        <entry><literal>windows_1252_to_utf8</literal></entry>
3063        <entry><literal>WIN1252</literal></entry>
3064        <entry><literal>UTF8</literal></entry>
3065       </row>
3066
3067       <row>
3068        <entry><literal>windows_1256_to_utf8</literal></entry>
3069        <entry><literal>WIN1256</literal></entry>
3070        <entry><literal>UTF8</literal></entry>
3071       </row>
3072
3073       <row>
3074        <entry><literal>windows_866_to_iso_8859_5</literal></entry>
3075        <entry><literal>WIN866</literal></entry>
3076        <entry><literal>ISO_8859_5</literal></entry>
3077       </row>
3078
3079       <row>
3080        <entry><literal>windows_866_to_koi8_r</literal></entry>
3081        <entry><literal>WIN866</literal></entry>
3082        <entry><literal>KOI8R</literal></entry>
3083       </row>
3084
3085       <row>
3086        <entry><literal>windows_866_to_mic</literal></entry>
3087        <entry><literal>WIN866</literal></entry>
3088        <entry><literal>MULE_INTERNAL</literal></entry>
3089       </row>
3090
3091       <row>
3092        <entry><literal>windows_866_to_utf8</literal></entry>
3093        <entry><literal>WIN866</literal></entry>
3094        <entry><literal>UTF8</literal></entry>
3095       </row>
3096
3097       <row>
3098        <entry><literal>windows_866_to_windows_1251</literal></entry>
3099        <entry><literal>WIN866</literal></entry>
3100        <entry><literal>WIN</literal></entry>
3101       </row>
3102
3103       <row>
3104        <entry><literal>windows_874_to_utf8</literal></entry>
3105        <entry><literal>WIN874</literal></entry>
3106        <entry><literal>UTF8</literal></entry>
3107       </row>
3108
3109       <row>
3110        <entry><literal>euc_jis_2004_to_utf8</literal></entry>
3111        <entry><literal>EUC_JIS_2004</literal></entry>
3112        <entry><literal>UTF8</literal></entry>
3113       </row>
3114
3115       <row>
3116        <entry><literal>utf8_to_euc_jis_2004</literal></entry>
3117        <entry><literal>UTF8</literal></entry>
3118        <entry><literal>EUC_JIS_2004</literal></entry>
3119       </row>
3120
3121       <row>
3122        <entry><literal>shift_jis_2004_to_utf8</literal></entry>
3123        <entry><literal>SHIFT_JIS_2004</literal></entry>
3124        <entry><literal>UTF8</literal></entry>
3125       </row>
3126
3127       <row>
3128        <entry><literal>utf8_to_shift_jis_2004</literal></entry>
3129        <entry><literal>UTF8</literal></entry>
3130        <entry><literal>SHIFT_JIS_2004</literal></entry>
3131       </row>
3132
3133       <row>
3134        <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
3135        <entry><literal>EUC_JIS_2004</literal></entry>
3136        <entry><literal>SHIFT_JIS_2004</literal></entry>
3137       </row>
3138
3139       <row>
3140        <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
3141        <entry><literal>SHIFT_JIS_2004</literal></entry>
3142        <entry><literal>EUC_JIS_2004</literal></entry>
3143       </row>
3144
3145      </tbody>
3146     </tgroup>
3147    </table>
3148
3149    <sect2 id="functions-string-format">
3150     <title><function>format</function></title>
3151
3152     <indexterm>
3153      <primary>format</primary>
3154     </indexterm>
3155
3156     <para>
3157      The function <function>format</> produces output formatted according to
3158      a format string, in a style similar to the C function
3159      <function>sprintf</>.
3160     </para>
3161
3162     <para>
3163 <synopsis>
3164 <function>format</>(<parameter>formatstr</> <type>text</> [, <parameter>formatarg</> <type>"any"</> [, ...] ])
3165 </synopsis>
3166      <replaceable>formatstr</> is a format string that specifies how the
3167      result should be formatted.  Text in the format string is copied
3168      directly to the result, except where <firstterm>format specifiers</> are
3169      used.  Format specifiers act as placeholders in the string, defining how
3170      subsequent function arguments should be formatted and inserted into the
3171      result.  Each <replaceable>formatarg</> argument is converted to text
3172      according to the usual output rules for its data type, and then formatted
3173      and inserted into the result string according to the format specifier(s).
3174     </para>
3175
3176     <para>
3177      Format specifiers are introduced by a <literal>%</> character and have
3178      the form
3179 <synopsis>
3180 %[<replaceable>position</>][<replaceable>flags</>][<replaceable>width</>]<replaceable>type</>
3181 </synopsis>
3182      where the component fields are:
3183
3184      <variablelist>
3185       <varlistentry>
3186        <term><replaceable>position</replaceable> (optional)</term>
3187        <listitem>
3188         <para>
3189          A string of the form <literal><replaceable>n</>$</> where
3190          <replaceable>n</> is the index of the argument to print.
3191          Index 1 means the first argument after
3192          <replaceable>formatstr</>.  If the <replaceable>position</> is
3193          omitted, the default is to use the next argument in sequence.
3194         </para>
3195        </listitem>
3196       </varlistentry>
3197
3198       <varlistentry>
3199        <term><replaceable>flags</replaceable> (optional)</term>
3200        <listitem>
3201         <para>
3202          Additional options controlling how the format specifier's output is
3203          formatted.  Currently the only supported flag is a minus sign
3204          (<literal>-</>) which will cause the format specifier's output to be
3205          left-justified.  This has no effect unless the <replaceable>width</>
3206          field is also specified.
3207         </para>
3208        </listitem>
3209       </varlistentry>
3210
3211       <varlistentry>
3212        <term><replaceable>width</replaceable> (optional)</term>
3213        <listitem>
3214         <para>
3215          Specifies the <emphasis>minimum</> number of characters to use to
3216          display the format specifier's output.  The output is padded on the
3217          left or right (depending on the <literal>-</> flag) with spaces as
3218          needed to fill the width.  A too-small width does not cause
3219          truncation of the output, but is simply ignored.  The width may be
3220          specified using any of the following: a positive integer; an
3221          asterisk (<literal>*</>) to use the next function argument as the
3222          width; or a string of the form <literal>*<replaceable>n</>$</> to
3223          use the <replaceable>n</>th function argument as the width.
3224         </para>
3225
3226         <para>
3227          If the width comes from a function argument, that argument is
3228          consumed before the argument that is used for the format specifier's
3229          value.  If the width argument is negative, the result is left
3230          aligned (as if the <literal>-</> flag had been specified) within a
3231          field of length <function>abs</>(<replaceable>width</replaceable>).
3232         </para>
3233        </listitem>
3234       </varlistentry>
3235
3236       <varlistentry>
3237        <term><replaceable>type</replaceable> (required)</term>
3238        <listitem>
3239         <para>
3240          The type of format conversion to use to produce the format
3241          specifier's output.  The following types are supported:
3242          <itemizedlist>
3243           <listitem>
3244            <para>
3245             <literal>s</literal> formats the argument value as a simple
3246             string.  A null value is treated as an empty string.
3247            </para>
3248           </listitem>
3249           <listitem>
3250            <para>
3251             <literal>I</literal> treats the argument value as an SQL
3252             identifier, double-quoting it if necessary.
3253             It is an error for the value to be null (equivalent to
3254             <function>quote_ident</>).
3255            </para>
3256           </listitem>
3257           <listitem>
3258            <para>
3259             <literal>L</literal> quotes the argument value as an SQL literal.
3260             A null value is displayed as the string <literal>NULL</>, without
3261             quotes (equivalent to <function>quote_nullable</function>).
3262            </para>
3263           </listitem>
3264          </itemizedlist>
3265         </para>
3266        </listitem>
3267       </varlistentry>
3268      </variablelist>
3269     </para>
3270
3271     <para>
3272      In addition to the format specifiers described above, the special sequence
3273      <literal>%%</> may be used to output a literal <literal>%</> character.
3274     </para>
3275
3276     <para>
3277      Here are some examples of the basic format conversions:
3278
3279 <screen>
3280 SELECT format('Hello %s', 'World');
3281 <lineannotation>Result: </lineannotation><computeroutput>Hello World</computeroutput>
3282
3283 SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
3284 <lineannotation>Result: </><computeroutput>Testing one, two, three, %</>
3285
3286 SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
3287 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO "Foo bar" VALUES('O''Reilly')</computeroutput>
3288
3289 SELECT format('INSERT INTO %I VALUES(%L)', 'locations', E'C:\\Program Files');
3290 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO locations VALUES(E'C:\\Program Files')</computeroutput>
3291 </screen>
3292     </para>
3293
3294     <para>
3295      Here are examples using <replaceable>width</replaceable> fields
3296      and the <literal>-</> flag:
3297
3298 <screen>
3299 SELECT format('|%10s|', 'foo');
3300 <lineannotation>Result: </><computeroutput>|       foo|</>
3301
3302 SELECT format('|%-10s|', 'foo');
3303 <lineannotation>Result: </><computeroutput>|foo       |</>
3304
3305 SELECT format('|%*s|', 10, 'foo');
3306 <lineannotation>Result: </><computeroutput>|       foo|</>
3307
3308 SELECT format('|%*s|', -10, 'foo');
3309 <lineannotation>Result: </><computeroutput>|foo       |</>
3310
3311 SELECT format('|%-*s|', 10, 'foo');
3312 <lineannotation>Result: </><computeroutput>|foo       |</>
3313
3314 SELECT format('|%-*s|', -10, 'foo');
3315 <lineannotation>Result: </><computeroutput>|foo       |</>
3316 </screen>
3317     </para>
3318
3319     <para>
3320      These examples show use of <replaceable>position</> fields:
3321
3322 <screen>
3323 SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three');
3324 <lineannotation>Result: </><computeroutput>Testing three, two, one</>
3325
3326 SELECT format('|%*2$s|', 'foo', 10, 'bar');
3327 <lineannotation>Result: </><computeroutput>|       bar|</>
3328
3329 SELECT format('|%1$*2$s|', 'foo', 10, 'bar');
3330 <lineannotation>Result: </><computeroutput>|       foo|</>
3331 </screen>
3332     </para>
3333
3334     <para>
3335      Unlike the standard C function <function>sprintf</>,
3336      <productname>PostgreSQL</>'s <function>format</> function allows format
3337      specifiers with and without <replaceable>position</> fields to be mixed
3338      in the same format string.  A format specifier without a
3339      <replaceable>position</> field always uses the next argument after the
3340      last argument consumed.
3341      In addition, the <function>format</> function does not require all
3342      function arguments to be used in the format string.
3343      For example:
3344
3345 <screen>
3346 SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three');
3347 <lineannotation>Result: </><computeroutput>Testing three, two, three</>
3348 </screen>
3349     </para>
3350
3351     <para>
3352      The <literal>%I</> and <literal>%L</> format specifiers are particularly
3353      useful for safely constructing dynamic SQL statements.  See
3354      <xref linkend="plpgsql-quote-literal-example">.
3355     </para>
3356    </sect2>
3357
3358   </sect1>
3359
3360
3361   <sect1 id="functions-binarystring">
3362    <title>Binary String Functions and Operators</title>
3363
3364    <indexterm zone="functions-binarystring">
3365     <primary>binary data</primary>
3366     <secondary>functions</secondary>
3367    </indexterm>
3368
3369    <para>
3370     This section describes functions and operators for examining and
3371     manipulating values of type <type>bytea</type>.
3372    </para>
3373
3374    <para>
3375     <acronym>SQL</acronym> defines some string functions that use
3376     key words, rather than commas, to separate
3377     arguments.  Details are in
3378     <xref linkend="functions-binarystring-sql">.
3379     <productname>PostgreSQL</> also provides versions of these functions
3380     that use the regular function invocation syntax
3381     (see <xref linkend="functions-binarystring-other">).
3382    </para>
3383
3384    <note>
3385     <para>
3386      The sample results shown on this page assume that the server parameter
3387      <link linkend="guc-bytea-output"><varname>bytea_output</></link> is set
3388      to <literal>escape</literal> (the traditional PostgreSQL format).
3389     </para>
3390    </note>
3391
3392    <table id="functions-binarystring-sql">
3393     <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
3394     <tgroup cols="5">
3395      <thead>
3396       <row>
3397        <entry>Function</entry>
3398        <entry>Return Type</entry>
3399        <entry>Description</entry>
3400        <entry>Example</entry>
3401        <entry>Result</entry>
3402       </row>
3403      </thead>
3404
3405      <tbody>
3406       <row>
3407        <entry><literal><parameter>string</parameter> <literal>||</literal>
3408         <parameter>string</parameter></literal></entry>
3409        <entry> <type>bytea</type> </entry>
3410        <entry>
3411         String concatenation
3412         <indexterm>
3413          <primary>binary string</primary>
3414          <secondary>concatenation</secondary>
3415         </indexterm>
3416        </entry>
3417        <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
3418        <entry><literal>\\Post'gres\000</literal></entry>
3419       </row>
3420
3421       <row>
3422        <entry>
3423         <indexterm>
3424          <primary>octet_length</primary>
3425         </indexterm>
3426         <literal><function>octet_length(<parameter>string</parameter>)</function></literal>
3427        </entry>
3428        <entry><type>int</type></entry>
3429        <entry>Number of bytes in binary string</entry>
3430        <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
3431        <entry><literal>5</literal></entry>
3432       </row>
3433
3434       <row>
3435        <entry>
3436         <indexterm>
3437          <primary>overlay</primary>
3438         </indexterm>
3439         <literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
3440        </entry>
3441        <entry><type>bytea</type></entry>
3442        <entry>
3443         Replace substring
3444        </entry>
3445        <entry><literal>overlay(E'Th\\000omas'::bytea placing E'\\002\\003'::bytea from 2 for 3)</literal></entry>
3446        <entry><literal>T\\002\\003mas</literal></entry>
3447       </row>
3448
3449       <row>
3450        <entry>
3451         <indexterm>
3452          <primary>position</primary>
3453         </indexterm>
3454         <literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
3455        </entry>
3456        <entry><type>int</type></entry>
3457        <entry>Location of specified substring</entry>
3458       <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
3459        <entry><literal>3</literal></entry>
3460       </row>
3461
3462       <row>
3463        <entry>
3464         <indexterm>
3465          <primary>substring</primary>
3466         </indexterm>
3467         <literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
3468        </entry>
3469        <entry><type>bytea</type></entry>
3470        <entry>
3471         Extract substring
3472        </entry>
3473        <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
3474        <entry><literal>h\000o</literal></entry>
3475       </row>
3476
3477       <row>
3478        <entry>
3479         <indexterm>
3480          <primary>trim</primary>
3481         </indexterm>
3482         <literal><function>trim(<optional>both</optional>
3483         <parameter>bytes</parameter> from
3484         <parameter>string</parameter>)</function></literal>
3485        </entry>
3486        <entry><type>bytea</type></entry>
3487        <entry>
3488         Remove the longest string containing only bytes appearing in
3489         <parameter>bytes</parameter> from the start
3490         and end of <parameter>string</parameter>
3491        </entry>
3492        <entry><literal>trim(E'\\000\\001'::bytea from E'\\000Tom\\001'::bytea)</literal></entry>
3493        <entry><literal>Tom</literal></entry>
3494       </row>
3495      </tbody>
3496     </tgroup>
3497    </table>
3498
3499    <para>
3500     Additional binary string manipulation functions are available and
3501     are listed in <xref linkend="functions-binarystring-other">.  Some
3502     of them are used internally to implement the
3503     <acronym>SQL</acronym>-standard string functions listed in <xref
3504     linkend="functions-binarystring-sql">.
3505    </para>
3506
3507    <table id="functions-binarystring-other">
3508     <title>Other Binary String Functions</title>
3509     <tgroup cols="5">
3510      <thead>
3511       <row>
3512        <entry>Function</entry>
3513        <entry>Return Type</entry>
3514        <entry>Description</entry>
3515        <entry>Example</entry>
3516        <entry>Result</entry>
3517       </row>
3518      </thead>
3519
3520      <tbody>
3521       <row>
3522        <entry>
3523         <indexterm>
3524          <primary>btrim</primary>
3525         </indexterm>
3526         <literal><function>btrim(<parameter>string</parameter>
3527         <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</function></literal>
3528        </entry>
3529        <entry><type>bytea</type></entry>
3530        <entry>
3531         Remove the longest string containing only bytes appearing in
3532         <parameter>bytes</parameter> from the start and end of
3533         <parameter>string</parameter>
3534       </entry>
3535       <entry><literal>btrim(E'\\000trim\\001'::bytea, E'\\000\\001'::bytea)</literal></entry>
3536       <entry><literal>trim</literal></entry>
3537      </row>
3538
3539      <row>
3540       <entry>
3541         <indexterm>
3542          <primary>decode</primary>
3543         </indexterm>
3544        <literal><function>decode(<parameter>string</parameter> <type>text</type>,
3545        <parameter>format</parameter> <type>text</type>)</function></literal>
3546       </entry>
3547       <entry><type>bytea</type></entry>
3548       <entry>
3549        Decode binary data from textual representation in <parameter>string</>.
3550        Options for <parameter>format</> are same as in <function>encode</>.
3551       </entry>
3552       <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
3553       <entry><literal>123\000456</literal></entry>
3554      </row>
3555
3556      <row>
3557       <entry>
3558         <indexterm>
3559          <primary>encode</primary>
3560         </indexterm>
3561        <literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
3562        <parameter>format</parameter> <type>text</type>)</function></literal>
3563       </entry>
3564       <entry><type>text</type></entry>
3565       <entry>
3566        Encode binary data into a textual representation.  Supported
3567        formats are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
3568        <literal>escape</> converts zero bytes and high-bit-set bytes to
3569        octal sequences (<literal>\</><replaceable>nnn</>) and
3570        doubles backslashes.
3571       </entry>
3572       <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
3573       <entry><literal>123\000456</literal></entry>
3574      </row>
3575
3576       <row>
3577        <entry>
3578         <indexterm>
3579          <primary>get_bit</primary>
3580         </indexterm>
3581         <literal><function>get_bit(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3582        </entry>
3583        <entry><type>int</type></entry>
3584        <entry>
3585         Extract bit from string
3586        </entry>
3587        <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
3588        <entry><literal>1</literal></entry>
3589       </row>
3590
3591       <row>
3592        <entry>
3593         <indexterm>
3594          <primary>get_byte</primary>
3595         </indexterm>
3596         <literal><function>get_byte(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
3597        </entry>
3598        <entry><type>int</type></entry>
3599        <entry>
3600         Extract byte from string
3601        </entry>
3602        <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
3603        <entry><literal>109</literal></entry>
3604       </row>
3605
3606      <row>
3607       <entry>
3608        <indexterm>
3609         <primary>length</primary>
3610        </indexterm>
3611        <literal><function>length(<parameter>string</parameter>)</function></literal>
3612       </entry>
3613       <entry><type>int</type></entry>
3614       <entry>
3615        Length of binary string
3616        <indexterm>
3617         <primary>binary string</primary>
3618         <secondary>length</secondary>
3619        </indexterm>
3620        <indexterm>
3621         <primary>length</primary>
3622         <secondary sortas="binary string">of a binary string</secondary>
3623         <see>binary strings, length</see>
3624        </indexterm>
3625       </entry>
3626       <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
3627       <entry><literal>5</literal></entry>
3628      </row>
3629
3630      <row>
3631       <entry>
3632        <indexterm>
3633         <primary>md5</primary>
3634        </indexterm>
3635        <literal><function>md5(<parameter>string</parameter>)</function></literal>
3636       </entry>
3637       <entry><type>text</type></entry>
3638       <entry>
3639        Calculates the MD5 hash of <parameter>string</parameter>,
3640        returning the result in hexadecimal
3641       </entry>
3642       <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
3643       <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
3644      </row>
3645
3646       <row>
3647        <entry>
3648         <indexterm>
3649          <primary>set_bit</primary>
3650         </indexterm>
3651         <literal><function>set_bit(<parameter>string</parameter>,
3652         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3653        </entry>
3654        <entry><type>bytea</type></entry>
3655        <entry>
3656         Set bit in string
3657        </entry>
3658        <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
3659        <entry><literal>Th\000omAs</literal></entry>
3660       </row>
3661
3662       <row>
3663        <entry>
3664         <indexterm>
3665          <primary>set_byte</primary>
3666         </indexterm>
3667         <literal><function>set_byte(<parameter>string</parameter>,
3668         <parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
3669        </entry>
3670        <entry><type>bytea</type></entry>
3671        <entry>
3672         Set byte in string
3673        </entry>
3674        <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
3675        <entry><literal>Th\000o@as</literal></entry>
3676       </row>
3677     </tbody>
3678    </tgroup>
3679   </table>
3680
3681   <para>
3682    <function>get_byte</> and <function>set_byte</> number the first byte
3683    of a binary string as byte 0.
3684    <function>get_bit</> and <function>set_bit</> number bits from the
3685    right within each byte; for example bit 0 is the least significant bit of
3686    the first byte, and bit 15 is the most significant bit of the second byte.
3687   </para>
3688
3689   <para>
3690    See also the aggregate function <function>string_agg</function> in
3691    <xref linkend="functions-aggregate"> and the large object functions
3692    in <xref linkend="lo-funcs">.
3693   </para>
3694  </sect1>
3695
3696
3697   <sect1 id="functions-bitstring">
3698    <title>Bit String Functions and Operators</title>
3699
3700    <indexterm zone="functions-bitstring">
3701     <primary>bit strings</primary>
3702     <secondary>functions</secondary>
3703    </indexterm>
3704
3705    <para>
3706     This section describes functions and operators for examining and
3707     manipulating bit strings, that is values of the types
3708     <type>bit</type> and <type>bit varying</type>.  Aside from the
3709     usual comparison operators, the operators
3710     shown in <xref linkend="functions-bit-string-op-table"> can be used.
3711     Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
3712     and <literal>#</literal> must be of equal length.  When bit
3713     shifting, the original length of the string is preserved, as shown
3714     in the examples.
3715    </para>
3716
3717    <table id="functions-bit-string-op-table">
3718     <title>Bit String Operators</title>
3719
3720     <tgroup cols="4">
3721      <thead>
3722       <row>
3723        <entry>Operator</entry>
3724        <entry>Description</entry>
3725        <entry>Example</entry>
3726        <entry>Result</entry>
3727       </row>
3728      </thead>
3729
3730      <tbody>
3731       <row>
3732        <entry> <literal>||</literal> </entry>
3733        <entry>concatenation</entry>
3734        <entry><literal>B'10001' || B'011'</literal></entry>
3735        <entry><literal>10001011</literal></entry>
3736       </row>
3737
3738       <row>
3739        <entry> <literal>&amp;</literal> </entry>
3740        <entry>bitwise AND</entry>
3741        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
3742        <entry><literal>00001</literal></entry>
3743       </row>
3744
3745       <row>
3746        <entry> <literal>|</literal> </entry>
3747        <entry>bitwise OR</entry>
3748        <entry><literal>B'10001' | B'01101'</literal></entry>
3749        <entry><literal>11101</literal></entry>
3750       </row>
3751
3752       <row>
3753        <entry> <literal>#</literal> </entry>
3754        <entry>bitwise XOR</entry>
3755        <entry><literal>B'10001' # B'01101'</literal></entry>
3756        <entry><literal>11100</literal></entry>
3757       </row>
3758
3759       <row>
3760        <entry> <literal>~</literal> </entry>
3761        <entry>bitwise NOT</entry>
3762        <entry><literal>~ B'10001'</literal></entry>
3763        <entry><literal>01110</literal></entry>
3764       </row>
3765
3766       <row>
3767        <entry> <literal>&lt;&lt;</literal> </entry>
3768        <entry>bitwise shift left</entry>
3769        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
3770        <entry><literal>01000</literal></entry>
3771       </row>
3772
3773       <row>
3774        <entry> <literal>&gt;&gt;</literal> </entry>
3775        <entry>bitwise shift right</entry>
3776        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
3777        <entry><literal>00100</literal></entry>
3778       </row>
3779      </tbody>
3780     </tgroup>
3781    </table>
3782
3783    <para>
3784     The following <acronym>SQL</acronym>-standard functions work on bit
3785     strings as well as character strings:
3786     <literal><function>length</function></literal>,
3787     <literal><function>bit_length</function></literal>,
3788     <literal><function>octet_length</function></literal>,
3789     <literal><function>position</function></literal>,
3790     <literal><function>substring</function></literal>,
3791     <literal><function>overlay</function></literal>.
3792    </para>
3793
3794    <para>
3795     The following functions work on bit strings as well as binary
3796     strings:
3797     <literal><function>get_bit</function></literal>,
3798     <literal><function>set_bit</function></literal>.
3799     When working with a bit string, these functions number the first
3800     (leftmost) bit of the string as bit 0.
3801    </para>
3802
3803    <para>
3804     In addition, it is possible to cast integral values to and from type
3805     <type>bit</>.
3806     Some examples:
3807 <programlisting>
3808 44::bit(10)                    <lineannotation>0000101100</lineannotation>
3809 44::bit(3)                     <lineannotation>100</lineannotation>
3810 cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
3811 '1110'::bit(4)::integer        <lineannotation>14</lineannotation>
3812 </programlisting>
3813     Note that casting to just <quote>bit</> means casting to
3814     <literal>bit(1)</>, and so will deliver only the least significant
3815     bit of the integer.
3816    </para>
3817
3818     <note>
3819      <para>
3820       Casting an integer to <type>bit(n)</> copies the rightmost
3821       <literal>n</> bits.  Casting an integer to a bit string width wider
3822       than the integer itself will sign-extend on the left.
3823      </para>
3824     </note>
3825
3826   </sect1>
3827
3828
3829  <sect1 id="functions-matching">
3830   <title>Pattern Matching</title>
3831
3832   <indexterm zone="functions-matching">
3833    <primary>pattern matching</primary>
3834   </indexterm>
3835
3836    <para>
3837     There are three separate approaches to pattern matching provided
3838     by <productname>PostgreSQL</productname>: the traditional
3839     <acronym>SQL</acronym> <function>LIKE</function> operator, the
3840     more recent <function>SIMILAR TO</function> operator (added in
3841     SQL:1999), and <acronym>POSIX</acronym>-style regular
3842     expressions.  Aside from the basic <quote>does this string match
3843     this pattern?</> operators, functions are available to extract
3844     or replace matching substrings and to split a string at matching
3845     locations.
3846    </para>
3847
3848    <tip>
3849     <para>
3850      If you have pattern matching needs that go beyond this,
3851      consider writing a user-defined function in Perl or Tcl.
3852     </para>
3853    </tip>
3854
3855    <caution>
3856     <para>
3857      While most regular-expression searches can be executed very quickly,
3858      regular expressions can be contrived that take arbitrary amounts of
3859      time and memory to process.  Be wary of accepting regular-expression
3860      search patterns from hostile sources.  If you must do so, it is
3861      advisable to impose a statement timeout.
3862     </para>
3863
3864     <para>
3865      Searches using <function>SIMILAR TO</function> patterns have the same
3866      security hazards, since <function>SIMILAR TO</function> provides many
3867      of the same capabilities as <acronym>POSIX</acronym>-style regular
3868      expressions.
3869     </para>
3870
3871     <para>
3872      <function>LIKE</function> searches, being much simpler than the other
3873      two options, are safer to use with possibly-hostile pattern sources.
3874     </para>
3875    </caution>
3876
3877   <sect2 id="functions-like">
3878    <title><function>LIKE</function></title>
3879
3880    <indexterm>
3881     <primary>LIKE</primary>
3882    </indexterm>
3883
3884 <synopsis>
3885 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3886 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3887 </synopsis>
3888
3889     <para>
3890      The <function>LIKE</function> expression returns true if the
3891      <replaceable>string</replaceable> matches the supplied
3892      <replaceable>pattern</replaceable>.  (As
3893      expected, the <function>NOT LIKE</function> expression returns
3894      false if <function>LIKE</function> returns true, and vice versa.
3895      An equivalent expression is
3896      <literal>NOT (<replaceable>string</replaceable> LIKE
3897       <replaceable>pattern</replaceable>)</literal>.)
3898     </para>
3899
3900     <para>
3901      If <replaceable>pattern</replaceable> does not contain percent
3902      signs or underscores, then the pattern only represents the string
3903      itself; in that case <function>LIKE</function> acts like the
3904      equals operator.  An underscore (<literal>_</literal>) in
3905      <replaceable>pattern</replaceable> stands for (matches) any single
3906      character; a percent sign (<literal>%</literal>) matches any sequence
3907      of zero or more characters.
3908     </para>
3909
3910    <para>
3911     Some examples:
3912 <programlisting>
3913 'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
3914 'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
3915 'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
3916 'abc' LIKE 'c'      <lineannotation>false</lineannotation>
3917 </programlisting>
3918    </para>
3919
3920    <para>
3921     <function>LIKE</function> pattern matching always covers the entire
3922     string.  Therefore, if it's desired to match a sequence anywhere within
3923     a string, the pattern must start and end with a percent sign.
3924    </para>
3925
3926    <para>
3927     To match a literal underscore or percent sign without matching
3928     other characters, the respective character in
3929     <replaceable>pattern</replaceable> must be
3930     preceded by the escape character.  The default escape
3931     character is the backslash but a different one can be selected by
3932     using the <literal>ESCAPE</literal> clause.  To match the escape
3933     character itself, write two escape characters.
3934    </para>
3935
3936    <note>
3937     <para>
3938      If you have <xref linkend="guc-standard-conforming-strings"> turned off,
3939      any backslashes you write in literal string constants will need to be
3940      doubled.  See <xref linkend="sql-syntax-strings"> for more information.
3941     </para>
3942    </note>
3943
3944    <para>
3945     It's also possible to select no escape character by writing
3946     <literal>ESCAPE ''</literal>.  This effectively disables the
3947     escape mechanism, which makes it impossible to turn off the
3948     special meaning of underscore and percent signs in the pattern.
3949    </para>
3950
3951    <para>
3952     The key word <token>ILIKE</token> can be used instead of
3953     <token>LIKE</token> to make the match case-insensitive according
3954     to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
3955     <productname>PostgreSQL</productname> extension.
3956    </para>
3957
3958    <para>
3959     The operator <literal>~~</literal> is equivalent to
3960     <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3961     <function>ILIKE</function>.  There are also
3962     <literal>!~~</literal> and <literal>!~~*</literal> operators that
3963     represent <function>NOT LIKE</function> and <function>NOT
3964     ILIKE</function>, respectively.  All of these operators are
3965     <productname>PostgreSQL</productname>-specific.
3966    </para>
3967   </sect2>
3968
3969
3970   <sect2 id="functions-similarto-regexp">
3971    <title><function>SIMILAR TO</function> Regular Expressions</title>
3972
3973    <indexterm>
3974     <primary>regular expression</primary>
3975     <!-- <seealso>pattern matching</seealso> breaks index build -->
3976    </indexterm>
3977
3978    <indexterm>
3979     <primary>SIMILAR TO</primary>
3980    </indexterm>
3981    <indexterm>
3982     <primary>substring</primary>
3983    </indexterm>
3984
3985 <synopsis>
3986 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3987 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3988 </synopsis>
3989
3990    <para>
3991     The <function>SIMILAR TO</function> operator returns true or
3992     false depending on whether its pattern matches the given string.
3993     It is similar to <function>LIKE</function>, except that it
3994     interprets the pattern using the SQL standard's definition of a
3995     regular expression.  SQL regular expressions are a curious cross
3996     between <function>LIKE</function> notation and common regular
3997     expression notation.
3998    </para>
3999
4000    <para>
4001     Like <function>LIKE</function>, the <function>SIMILAR TO</function>
4002     operator succeeds only if its pattern matches the entire string;
4003     this is unlike common regular expression behavior where the pattern
4004     can match any part of the string.
4005     Also like
4006     <function>LIKE</function>, <function>SIMILAR TO</function> uses
4007     <literal>_</> and <literal>%</> as wildcard characters denoting
4008     any single character and any string, respectively (these are
4009     comparable to <literal>.</> and <literal>.*</> in POSIX regular
4010     expressions).
4011    </para>
4012
4013    <para>
4014     In addition to these facilities borrowed from <function>LIKE</function>,
4015     <function>SIMILAR TO</function> supports these pattern-matching
4016     metacharacters borrowed from POSIX regular expressions:
4017
4018    <itemizedlist>
4019     <listitem>
4020      <para>
4021       <literal>|</literal> denotes alternation (either of two alternatives).
4022      </para>
4023     </listitem>
4024     <listitem>
4025      <para>
4026       <literal>*</literal> denotes repetition of the previous item zero
4027       or more times.
4028      </para>
4029     </listitem>
4030     <listitem>
4031      <para>
4032       <literal>+</literal> denotes repetition of the previous item one
4033       or more times.
4034      </para>
4035     </listitem>
4036     <listitem>
4037      <para>
4038       <literal>?</literal> denotes repetition of the previous item zero
4039       or one time.
4040      </para>
4041     </listitem>
4042     <listitem>
4043      <para>
4044       <literal>{</><replaceable>m</><literal>}</literal> denotes repetition
4045       of the previous item exactly <replaceable>m</> times.
4046      </para>
4047     </listitem>
4048     <listitem>
4049      <para>
4050       <literal>{</><replaceable>m</><literal>,}</literal> denotes repetition
4051       of the previous item <replaceable>m</> or more times.
4052      </para>
4053     </listitem>
4054     <listitem>
4055      <para>
4056       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4057       denotes repetition of the previous item at least <replaceable>m</> and
4058       not more than <replaceable>n</> times.
4059      </para>
4060     </listitem>
4061     <listitem>
4062      <para>
4063       Parentheses <literal>()</literal> can be used to group items into
4064       a single logical item.
4065      </para>
4066     </listitem>
4067     <listitem>
4068      <para>
4069       A bracket expression <literal>[...]</literal> specifies a character
4070       class, just as in POSIX regular expressions.
4071      </para>
4072     </listitem>
4073    </itemizedlist>
4074
4075     Notice that the period (<literal>.</>) is not a metacharacter
4076     for <function>SIMILAR TO</>.
4077    </para>
4078
4079    <para>
4080     As with <function>LIKE</>, a backslash disables the special meaning
4081     of any of these metacharacters; or a different escape character can
4082     be specified with <literal>ESCAPE</>.
4083    </para>
4084
4085    <para>
4086     Some examples:
4087 <programlisting>
4088 'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
4089 'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
4090 'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
4091 'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
4092 </programlisting>
4093    </para>
4094
4095    <para>
4096     The <function>substring</> function with three parameters,
4097     <function>substring(<replaceable>string</replaceable> from
4098     <replaceable>pattern</replaceable> for
4099     <replaceable>escape-character</replaceable>)</function>, provides
4100     extraction of a substring that matches an SQL
4101     regular expression pattern.  As with <literal>SIMILAR TO</>, the
4102     specified pattern must match the entire data string, or else the
4103     function fails and returns null.  To indicate the part of the
4104     pattern that should be returned on success, the pattern must contain
4105     two occurrences of the escape character followed by a double quote
4106     (<literal>"</>). <!-- " font-lock sanity -->
4107     The text matching the portion of the pattern
4108     between these markers is returned.
4109    </para>
4110
4111    <para>
4112     Some examples, with <literal>#&quot;</> delimiting the return string:
4113 <programlisting>
4114 substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
4115 substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
4116 </programlisting>
4117    </para>
4118   </sect2>
4119
4120   <sect2 id="functions-posix-regexp">
4121    <title><acronym>POSIX</acronym> Regular Expressions</title>
4122
4123    <indexterm zone="functions-posix-regexp">
4124     <primary>regular expression</primary>
4125     <seealso>pattern matching</seealso>
4126    </indexterm>
4127    <indexterm>
4128     <primary>substring</primary>
4129    </indexterm>
4130    <indexterm>
4131     <primary>regexp_replace</primary>
4132    </indexterm>
4133    <indexterm>
4134     <primary>regexp_match</primary>
4135    </indexterm>
4136    <indexterm>
4137     <primary>regexp_matches</primary>
4138    </indexterm>
4139    <indexterm>
4140     <primary>regexp_split_to_table</primary>
4141    </indexterm>
4142    <indexterm>
4143     <primary>regexp_split_to_array</primary>
4144    </indexterm>
4145
4146    <para>
4147     <xref linkend="functions-posix-table"> lists the available
4148     operators for pattern matching using POSIX regular expressions.
4149    </para>
4150
4151    <table id="functions-posix-table">
4152     <title>Regular Expression Match Operators</title>
4153
4154     <tgroup cols="3">
4155      <thead>
4156       <row>
4157        <entry>Operator</entry>
4158        <entry>Description</entry>
4159        <entry>Example</entry>
4160       </row>
4161      </thead>
4162
4163       <tbody>
4164        <row>
4165         <entry> <literal>~</literal> </entry>
4166         <entry>Matches regular expression, case sensitive</entry>
4167         <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
4168        </row>
4169
4170        <row>
4171         <entry> <literal>~*</literal> </entry>
4172         <entry>Matches regular expression, case insensitive</entry>
4173         <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
4174        </row>
4175
4176        <row>
4177         <entry> <literal>!~</literal> </entry>
4178         <entry>Does not match regular expression, case sensitive</entry>
4179         <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
4180        </row>
4181
4182        <row>
4183         <entry> <literal>!~*</literal> </entry>
4184         <entry>Does not match regular expression, case insensitive</entry>
4185         <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
4186        </row>
4187       </tbody>
4188      </tgroup>
4189     </table>
4190
4191     <para>
4192      <acronym>POSIX</acronym> regular expressions provide a more
4193      powerful means for pattern matching than the <function>LIKE</function> and
4194      <function>SIMILAR TO</> operators.
4195      Many Unix tools such as <command>egrep</command>,
4196      <command>sed</command>, or <command>awk</command> use a pattern
4197      matching language that is similar to the one described here.
4198     </para>
4199
4200     <para>
4201      A regular expression is a character sequence that is an
4202      abbreviated definition of a set of strings (a <firstterm>regular
4203      set</firstterm>).  A string is said to match a regular expression
4204      if it is a member of the regular set described by the regular
4205      expression.  As with <function>LIKE</function>, pattern characters
4206      match string characters exactly unless they are special characters
4207      in the regular expression language &mdash; but regular expressions use
4208      different special characters than <function>LIKE</function> does.
4209      Unlike <function>LIKE</function> patterns, a
4210      regular expression is allowed to match anywhere within a string, unless
4211      the regular expression is explicitly anchored to the beginning or
4212      end of the string.
4213     </para>
4214
4215     <para>
4216      Some examples:
4217 <programlisting>
4218 'abc' ~ 'abc'    <lineannotation>true</lineannotation>
4219 'abc' ~ '^a'     <lineannotation>true</lineannotation>
4220 'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
4221 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
4222 </programlisting>
4223     </para>
4224
4225     <para>
4226      The <acronym>POSIX</acronym> pattern language is described in much
4227      greater detail below.
4228     </para>
4229
4230     <para>
4231      The <function>substring</> function with two parameters,
4232      <function>substring(<replaceable>string</replaceable> from
4233      <replaceable>pattern</replaceable>)</function>, provides extraction of a
4234      substring
4235      that matches a POSIX regular expression pattern.  It returns null if
4236      there is no match, otherwise the portion of the text that matched the
4237      pattern.  But if the pattern contains any parentheses, the portion
4238      of the text that matched the first parenthesized subexpression (the
4239      one whose left parenthesis comes first) is
4240      returned.  You can put parentheses around the whole expression
4241      if you want to use parentheses within it without triggering this
4242      exception.  If you need parentheses in the pattern before the
4243      subexpression you want to extract, see the non-capturing parentheses
4244      described below.
4245     </para>
4246
4247    <para>
4248     Some examples:
4249 <programlisting>
4250 substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
4251 substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
4252 </programlisting>
4253    </para>
4254
4255     <para>
4256      The <function>regexp_replace</> function provides substitution of
4257      new text for substrings that match POSIX regular expression patterns.
4258      It has the syntax
4259      <function>regexp_replace</function>(<replaceable>source</>,
4260      <replaceable>pattern</>, <replaceable>replacement</>
4261      <optional>, <replaceable>flags</> </optional>).
4262      The <replaceable>source</> string is returned unchanged if
4263      there is no match to the <replaceable>pattern</>.  If there is a
4264      match, the <replaceable>source</> string is returned with the
4265      <replaceable>replacement</> string substituted for the matching
4266      substring.  The <replaceable>replacement</> string can contain
4267      <literal>\</><replaceable>n</>, where <replaceable>n</> is 1
4268      through 9, to indicate that the source substring matching the
4269      <replaceable>n</>'th parenthesized subexpression of the pattern should be
4270      inserted, and it can contain <literal>\&amp;</> to indicate that the
4271      substring matching the entire pattern should be inserted.  Write
4272      <literal>\\</> if you need to put a literal backslash in the replacement
4273      text.
4274      The <replaceable>flags</> parameter is an optional text
4275      string containing zero or more single-letter flags that change the
4276      function's behavior.  Flag <literal>i</> specifies case-insensitive
4277      matching, while flag <literal>g</> specifies replacement of each matching
4278      substring rather than only the first one.  Supported flags (though
4279      not <literal>g</>) are
4280      described in <xref linkend="posix-embedded-options-table">.
4281     </para>
4282
4283    <para>
4284     Some examples:
4285 <programlisting>
4286 regexp_replace('foobarbaz', 'b..', 'X')
4287                                    <lineannotation>fooXbaz</lineannotation>
4288 regexp_replace('foobarbaz', 'b..', 'X', 'g')
4289                                    <lineannotation>fooXX</lineannotation>
4290 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
4291                                    <lineannotation>fooXarYXazY</lineannotation>
4292 </programlisting>
4293    </para>
4294
4295     <para>
4296      The <function>regexp_match</> function returns a text array of
4297      captured substring(s) resulting from the first match of a POSIX
4298      regular expression pattern to a string.  It has the syntax
4299      <function>regexp_match</function>(<replaceable>string</>,
4300      <replaceable>pattern</> <optional>, <replaceable>flags</> </optional>).
4301      If there is no match, the result is <literal>NULL</>.
4302      If a match is found, and the <replaceable>pattern</> contains no
4303      parenthesized subexpressions, then the result is a single-element text
4304      array containing the substring matching the whole pattern.
4305      If a match is found, and the <replaceable>pattern</> contains
4306      parenthesized subexpressions, then the result is a text array
4307      whose <replaceable>n</>'th element is the substring matching
4308      the <replaceable>n</>'th parenthesized subexpression of
4309      the <replaceable>pattern</> (not counting <quote>non-capturing</>
4310      parentheses; see below for details).
4311      The <replaceable>flags</> parameter is an optional text string
4312      containing zero or more single-letter flags that change the function's
4313      behavior.  Supported flags are described
4314      in <xref linkend="posix-embedded-options-table">.
4315     </para>
4316
4317    <para>
4318     Some examples:
4319 <programlisting>
4320 SELECT regexp_match('foobarbequebaz', 'bar.*que');
4321  regexp_match
4322 --------------
4323  {barbeque}
4324 (1 row)
4325
4326 SELECT regexp_match('foobarbequebaz', '(bar)(beque)');
4327  regexp_match
4328 --------------
4329  {bar,beque}
4330 (1 row)
4331 </programlisting>
4332     In the common case where you just want the whole matching substring
4333     or <literal>NULL</> for no match, write something like
4334 <programlisting>
4335 SELECT (regexp_match('foobarbequebaz', 'bar.*que'))[1];
4336  regexp_match
4337 --------------
4338  barbeque
4339 (1 row)
4340 </programlisting>
4341    </para>
4342
4343     <para>
4344      The <function>regexp_matches</> function returns a set of text arrays
4345      of captured substring(s) resulting from matching a POSIX regular
4346      expression pattern to a string.  It has the same syntax as
4347      <function>regexp_match</function>.
4348      This function returns no rows if there is no match, one row if there is
4349      a match and the <literal>g</> flag is not given, or <replaceable>N</>
4350      rows if there are <replaceable>N</> matches and the <literal>g</> flag
4351      is given.  Each returned row is a text array containing the whole
4352      matched substring or the substrings matching parenthesized
4353      subexpressions of the <replaceable>pattern</>, just as described above
4354      for <function>regexp_match</function>.
4355      <function>regexp_matches</> accepts all the flags shown
4356      in <xref linkend="posix-embedded-options-table">, plus
4357      the <literal>g</> flag which commands it to return all matches, not
4358      just the first one.
4359     </para>
4360
4361    <para>
4362     Some examples:
4363 <programlisting>
4364  SELECT regexp_matches('foo', 'not there');
4365  regexp_matches
4366 ----------------
4367 (0 rows)
4368
4369 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
4370  regexp_matches
4371 ----------------
4372  {bar,beque}
4373  {bazil,barf}
4374 (2 rows)
4375 </programlisting>
4376    </para>
4377
4378    <tip>
4379     <para>
4380      In most cases <function>regexp_matches()</> should be used with
4381      the <literal>g</> flag, since if you only want the first match, it's
4382      easier and more efficient to use <function>regexp_match()</>.
4383      However, <function>regexp_match()</> only exists
4384      in <productname>PostgreSQL</> version 10 and up.  When working in older
4385      versions, a common trick is to place a <function>regexp_matches()</>
4386      call in a sub-select, for example:
4387 <programlisting>
4388 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
4389 </programlisting>
4390      This produces a text array if there's a match, or <literal>NULL</> if
4391      not, the same as <function>regexp_match()</> would do.  Without the
4392      sub-select, this query would produce no output at all for table rows
4393      without a match, which is typically not the desired behavior.
4394     </para>
4395    </tip>
4396
4397     <para>
4398      The <function>regexp_split_to_table</> function splits a string using a POSIX
4399      regular expression pattern as a delimiter.  It has the syntax
4400      <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
4401      <optional>, <replaceable>flags</> </optional>).
4402      If there is no match to the <replaceable>pattern</>, the function returns the
4403      <replaceable>string</>.  If there is at least one match, for each match it returns
4404      the text from the end of the last match (or the beginning of the string)
4405      to the beginning of the match.  When there are no more matches, it
4406      returns the text from the end of the last match to the end of the string.
4407      The <replaceable>flags</> parameter is an optional text string containing
4408      zero or more single-letter flags that change the function's behavior.
4409      <function>regexp_split_to_table</function> supports the flags described in
4410      <xref linkend="posix-embedded-options-table">.
4411     </para>
4412
4413     <para>
4414      The <function>regexp_split_to_array</> function behaves the same as
4415      <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
4416      returns its result as an array of <type>text</>.  It has the syntax
4417      <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
4418      <optional>, <replaceable>flags</> </optional>).
4419      The parameters are the same as for <function>regexp_split_to_table</>.
4420     </para>
4421
4422    <para>
4423     Some examples:
4424 <programlisting>
4425
4426 SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', E'\\s+') AS foo;
4427   foo   
4428 -------
4429  the    
4430  quick  
4431  brown  
4432  fox    
4433  jumps 
4434  over   
4435  the    
4436  lazy   
4437  dog    
4438 (9 rows)
4439
4440 SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', E'\\s+');
4441               regexp_split_to_array             
4442 -----------------------------------------------
4443  {the,quick,brown,fox,jumps,over,the,lazy,dog}
4444 (1 row)
4445
4446 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
4447  foo 
4448 -----
4449  t         
4450  h         
4451  e         
4452  q         
4453  u         
4454  i         
4455  c         
4456  k         
4457  b         
4458  r         
4459  o         
4460  w         
4461  n         
4462  f         
4463  o         
4464  x         
4465 (16 rows)
4466 </programlisting>
4467    </para>
4468
4469    <para>
4470     As the last example demonstrates, the regexp split functions ignore
4471     zero-length matches that occur at the start or end of the string
4472     or immediately after a previous match.  This is contrary to the strict
4473     definition of regexp matching that is implemented by
4474     <function>regexp_match</> and
4475     <function>regexp_matches</>, but is usually the most convenient behavior
4476     in practice.  Other software systems such as Perl use similar definitions.
4477    </para>
4478
4479 <!-- derived from the re_syntax.n man page -->
4480
4481    <sect3 id="posix-syntax-details">
4482     <title>Regular Expression Details</title>
4483
4484    <para>
4485     <productname>PostgreSQL</productname>'s regular expressions are implemented
4486     using a software package written by Henry Spencer.  Much of
4487     the description of regular expressions below is copied verbatim from his
4488     manual.
4489    </para>
4490
4491    <para>
4492     Regular expressions (<acronym>RE</acronym>s), as defined in
4493     <acronym>POSIX</acronym> 1003.2, come in two forms:
4494     <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
4495     (roughly those of <command>egrep</command>), and
4496     <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
4497     (roughly those of <command>ed</command>).
4498     <productname>PostgreSQL</productname> supports both forms, and
4499     also implements some extensions
4500     that are not in the POSIX standard, but have become widely used
4501     due to their availability in programming languages such as Perl and Tcl.
4502     <acronym>RE</acronym>s using these non-POSIX extensions are called
4503     <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
4504     in this documentation.  AREs are almost an exact superset of EREs,
4505     but BREs have several notational incompatibilities (as well as being
4506     much more limited).
4507     We first describe the ARE and ERE forms, noting features that apply
4508     only to AREs, and then describe how BREs differ.
4509    </para>
4510
4511    <note>
4512     <para>
4513      <productname>PostgreSQL</> always initially presumes that a regular
4514      expression follows the ARE rules.  However, the more limited ERE or
4515      BRE rules can be chosen by prepending an <firstterm>embedded option</>
4516      to the RE pattern, as described in <xref linkend="posix-metasyntax">.
4517      This can be useful for compatibility with applications that expect
4518      exactly the <acronym>POSIX</acronym> 1003.2 rules.
4519     </para>
4520    </note>
4521
4522    <para>
4523     A regular expression is defined as one or more
4524     <firstterm>branches</firstterm>, separated by
4525     <literal>|</literal>.  It matches anything that matches one of the
4526     branches.
4527    </para>
4528
4529    <para>
4530     A branch is zero or more <firstterm>quantified atoms</> or
4531     <firstterm>constraints</>, concatenated.
4532     It matches a match for the first, followed by a match for the second, etc;
4533     an empty branch matches the empty string.
4534    </para>
4535
4536    <para>
4537     A quantified atom is an <firstterm>atom</> possibly followed
4538     by a single <firstterm>quantifier</>.
4539     Without a quantifier, it matches a match for the atom.
4540     With a quantifier, it can match some number of matches of the atom.
4541     An <firstterm>atom</firstterm> can be any of the possibilities
4542     shown in <xref linkend="posix-atoms-table">.
4543     The possible quantifiers and their meanings are shown in
4544     <xref linkend="posix-quantifiers-table">.
4545    </para>
4546
4547    <para>
4548     A <firstterm>constraint</> matches an empty string, but matches only when
4549     specific conditions are met.  A constraint can be used where an atom
4550     could be used, except it cannot be followed by a quantifier.
4551     The simple constraints are shown in
4552     <xref linkend="posix-constraints-table">;
4553     some more constraints are described later.
4554    </para>
4555
4556
4557    <table id="posix-atoms-table">
4558     <title>Regular Expression Atoms</title>
4559
4560     <tgroup cols="2">
4561      <thead>
4562       <row>
4563        <entry>Atom</entry>
4564        <entry>Description</entry>
4565       </row>
4566      </thead>
4567
4568       <tbody>
4569        <row>
4570        <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
4571        <entry> (where <replaceable>re</> is any regular expression)
4572        matches a match for
4573        <replaceable>re</>, with the match noted for possible reporting </entry>
4574        </row>
4575
4576        <row>
4577        <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
4578        <entry> as above, but the match is not noted for reporting
4579        (a <quote>non-capturing</> set of parentheses)
4580        (AREs only) </entry>
4581        </row>
4582
4583        <row>
4584        <entry> <literal>.</> </entry>
4585        <entry> matches any single character </entry>
4586        </row>
4587
4588        <row>
4589        <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
4590        <entry> a <firstterm>bracket expression</>,
4591        matching any one of the <replaceable>chars</> (see
4592        <xref linkend="posix-bracket-expressions"> for more detail) </entry>
4593        </row>
4594
4595        <row>
4596        <entry> <literal>\</><replaceable>k</> </entry>
4597        <entry> (where <replaceable>k</> is a non-alphanumeric character)
4598        matches that character taken as an ordinary character,
4599        e.g., <literal>\\</> matches a backslash character </entry>
4600        </row>
4601
4602        <row>
4603        <entry> <literal>\</><replaceable>c</> </entry>
4604        <entry> where <replaceable>c</> is alphanumeric
4605        (possibly followed by other characters)
4606        is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
4607        (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
4608        </row>
4609
4610        <row>
4611        <entry> <literal>{</> </entry>
4612        <entry> when followed by a character other than a digit,
4613        matches the left-brace character <literal>{</>;
4614        when followed by a digit, it is the beginning of a
4615        <replaceable>bound</> (see below) </entry>
4616        </row>
4617
4618        <row>
4619        <entry> <replaceable>x</> </entry>
4620        <entry> where <replaceable>x</> is a single character with no other
4621        significance, matches that character </entry>
4622        </row>
4623       </tbody>
4624      </tgroup>
4625     </table>
4626
4627    <para>
4628     An RE cannot end with a backslash (<literal>\</>).
4629    </para>
4630
4631    <note>
4632     <para>
4633      If you have <xref linkend="guc-standard-conforming-strings"> turned off,
4634      any backslashes you write in literal string constants will need to be
4635      doubled.  See <xref linkend="sql-syntax-strings"> for more information.
4636     </para>
4637    </note>
4638
4639    <table id="posix-quantifiers-table">
4640     <title>Regular Expression Quantifiers</title>
4641
4642     <tgroup cols="2">
4643      <thead>
4644       <row>
4645        <entry>Quantifier</entry>
4646        <entry>Matches</entry>
4647       </row>
4648      </thead>
4649
4650       <tbody>
4651        <row>
4652        <entry> <literal>*</> </entry>
4653        <entry> a sequence of 0 or more matches of the atom </entry>
4654        </row>
4655
4656        <row>
4657        <entry> <literal>+</> </entry>
4658        <entry> a sequence of 1 or more matches of the atom </entry>
4659        </row>
4660
4661        <row>
4662        <entry> <literal>?</> </entry>
4663        <entry> a sequence of 0 or 1 matches of the atom </entry>
4664        </row>
4665
4666        <row>
4667        <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
4668        <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
4669        </row>
4670
4671        <row>
4672        <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
4673        <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
4674        </row>
4675
4676        <row>
4677        <entry>
4678        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4679        <entry> a sequence of <replaceable>m</> through <replaceable>n</>
4680        (inclusive) matches of the atom; <replaceable>m</> cannot exceed
4681        <replaceable>n</> </entry>
4682        </row>
4683
4684        <row>
4685        <entry> <literal>*?</> </entry>
4686        <entry> non-greedy version of <literal>*</> </entry>
4687        </row>
4688
4689        <row>
4690        <entry> <literal>+?</> </entry>
4691        <entry> non-greedy version of <literal>+</> </entry>
4692        </row>
4693
4694        <row>
4695        <entry> <literal>??</> </entry>
4696        <entry> non-greedy version of <literal>?</> </entry>
4697        </row>
4698
4699        <row>
4700        <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
4701        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
4702        </row>
4703
4704        <row>
4705        <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
4706        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
4707        </row>
4708
4709        <row>
4710        <entry>
4711        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
4712        <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
4713        </row>
4714       </tbody>
4715      </tgroup>
4716     </table>
4717
4718    <para>
4719     The forms using <literal>{</><replaceable>...</><literal>}</>
4720     are known as <firstterm>bounds</>.
4721     The numbers <replaceable>m</> and <replaceable>n</> within a bound are
4722     unsigned decimal integers with permissible values from 0 to 255 inclusive.
4723    </para>
4724
4725     <para>
4726      <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
4727      same possibilities as their corresponding normal (<firstterm>greedy</>)
4728      counterparts, but prefer the smallest number rather than the largest
4729      number of matches.
4730      See <xref linkend="posix-matching-rules"> for more detail.
4731    </para>
4732
4733    <note>
4734     <para>
4735      A quantifier cannot immediately follow another quantifier, e.g.,
4736      <literal>**</> is invalid.
4737      A quantifier cannot
4738      begin an expression or subexpression or follow
4739      <literal>^</literal> or <literal>|</literal>.
4740     </para>
4741    </note>
4742
4743    <table id="posix-constraints-table">
4744     <title>Regular Expression Constraints</title>
4745
4746     <tgroup cols="2">
4747      <thead>
4748       <row>
4749        <entry>Constraint</entry>
4750        <entry>Description</entry>
4751       </row>
4752      </thead>
4753
4754       <tbody>
4755        <row>
4756        <entry> <literal>^</> </entry>
4757        <entry> matches at the beginning of the string </entry>
4758        </row>
4759
4760        <row>
4761        <entry> <literal>$</> </entry>
4762        <entry> matches at the end of the string </entry>
4763        </row>
4764
4765        <row>
4766        <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
4767        <entry> <firstterm>positive lookahead</> matches at any point
4768        where a substring matching <replaceable>re</> begins
4769        (AREs only) </entry>
4770        </row>
4771
4772        <row>
4773        <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
4774        <entry> <firstterm>negative lookahead</> matches at any point
4775        where no substring matching <replaceable>re</> begins
4776        (AREs only) </entry>
4777        </row>
4778
4779        <row>
4780        <entry> <literal>(?&lt;=</><replaceable>re</><literal>)</> </entry>
4781        <entry> <firstterm>positive lookbehind</> matches at any point
4782        where a substring matching <replaceable>re</> ends
4783        (AREs only) </entry>
4784        </row>
4785
4786        <row>
4787        <entry> <literal>(?&lt;!</><replaceable>re</><literal>)</> </entry>
4788        <entry> <firstterm>negative lookbehind</> matches at any point
4789        where no substring matching <replaceable>re</> ends
4790        (AREs only) </entry>
4791        </row>
4792       </tbody>
4793      </tgroup>
4794     </table>
4795
4796    <para>
4797     Lookahead and lookbehind constraints cannot contain <firstterm>back
4798     references</> (see <xref linkend="posix-escape-sequences">),
4799     and all parentheses within them are considered non-capturing.
4800    </para>
4801    </sect3>
4802
4803    <sect3 id="posix-bracket-expressions">
4804     <title>Bracket Expressions</title>
4805
4806    <para>
4807     A <firstterm>bracket expression</firstterm> is a list of
4808     characters enclosed in <literal>[]</literal>.  It normally matches
4809     any single character from the list (but see below).  If the list
4810     begins with <literal>^</literal>, it matches any single character
4811     <emphasis>not</> from the rest of the list.
4812     If two characters
4813     in the list are separated by <literal>-</literal>, this is
4814     shorthand for the full range of characters between those two
4815     (inclusive) in the collating sequence,
4816     e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
4817     any decimal digit.  It is illegal for two ranges to share an
4818     endpoint, e.g.,  <literal>a-c-e</literal>.  Ranges are very
4819     collating-sequence-dependent, so portable programs should avoid
4820     relying on them.
4821    </para>
4822
4823    <para>
4824     To include a literal <literal>]</literal> in the list, make it the
4825     first character (after <literal>^</literal>, if that is used).  To
4826     include a literal <literal>-</literal>, make it the first or last
4827     character, or the second endpoint of a range.  To use a literal
4828     <literal>-</literal> as the first endpoint of a range, enclose it
4829     in <literal>[.</literal> and <literal>.]</literal> to make it a
4830     collating element (see below).  With the exception of these characters,
4831     some combinations using <literal>[</literal>
4832     (see next paragraphs), and escapes (AREs only), all other special
4833     characters lose their special significance within a bracket expression.
4834     In particular, <literal>\</literal> is not special when following
4835     ERE or BRE rules, though it is special (as introducing an escape)
4836     in AREs.
4837    </para>
4838
4839    <para>
4840     Within a bracket expression, a collating element (a character, a
4841     multiple-character sequence that collates as if it were a single
4842     character, or a collating-sequence name for either) enclosed in
4843     <literal>[.</literal> and <literal>.]</literal> stands for the
4844     sequence of characters of that collating element.  The sequence is
4845     treated as a single element of the bracket expression's list.  This
4846     allows a bracket
4847     expression containing a multiple-character collating element to
4848     match more than one character, e.g., if the collating sequence
4849     includes a <literal>ch</literal> collating element, then the RE
4850     <literal>[[.ch.]]*c</literal> matches the first five characters of
4851     <literal>chchcc</literal>.
4852    </para>
4853
4854    <note>
4855     <para>
4856      <productname>PostgreSQL</> currently does not support multi-character collating
4857      elements. This information describes possible future behavior.
4858     </para>
4859    </note>
4860
4861    <para>
4862     Within a bracket expression, a collating element enclosed in
4863     <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
4864     class</>, standing for the sequences of characters of all collating
4865     elements equivalent to that one, including itself.  (If there are
4866     no other equivalent collating elements, the treatment is as if the
4867     enclosing delimiters were <literal>[.</literal> and
4868     <literal>.]</literal>.)  For example, if <literal>o</literal> and
4869     <literal>^</literal> are the members of an equivalence class, then
4870     <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
4871     <literal>[o^]</literal> are all synonymous.  An equivalence class
4872     cannot be an endpoint of a range.
4873    </para>
4874
4875    <para>
4876     Within a bracket expression, the name of a character class
4877     enclosed in <literal>[:</literal> and <literal>:]</literal> stands
4878     for the list of all characters belonging to that class.  Standard
4879     character class names are: <literal>alnum</literal>,
4880     <literal>alpha</literal>, <literal>blank</literal>,
4881     <literal>cntrl</literal>, <literal>digit</literal>,
4882     <literal>graph</literal>, <literal>lower</literal>,
4883     <literal>print</literal>, <literal>punct</literal>,
4884     <literal>space</literal>, <literal>upper</literal>,
4885     <literal>xdigit</literal>.  These stand for the character classes
4886     defined in
4887     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
4888     A locale can provide others.  A character class cannot be used as
4889     an endpoint of a range.
4890    </para>
4891
4892    <para>
4893     There are two special cases of bracket expressions:  the bracket
4894     expressions <literal>[[:&lt;:]]</literal> and
4895     <literal>[[:&gt;:]]</literal> are constraints,
4896     matching empty strings at the beginning
4897     and end of a word respectively.  A word is defined as a sequence
4898     of word characters that is neither preceded nor followed by word
4899     characters.  A word character is an <literal>alnum</> character (as
4900     defined by
4901     <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
4902     or an underscore.  This is an extension, compatible with but not
4903     specified by <acronym>POSIX</acronym> 1003.2, and should be used with
4904     caution in software intended to be portable to other systems.
4905     The constraint escapes described below are usually preferable; they
4906     are no more standard, but are easier to type.
4907    </para>
4908    </sect3>
4909
4910    <sect3 id="posix-escape-sequences">
4911     <title>Regular Expression Escapes</title>
4912
4913    <para>
4914     <firstterm>Escapes</> are special sequences beginning with <literal>\</>
4915     followed by an alphanumeric character. Escapes come in several varieties:
4916     character entry, class shorthands, constraint escapes, and back references.
4917     A <literal>\</> followed by an alphanumeric character but not constituting
4918     a valid escape is illegal in AREs.
4919     In EREs, there are no escapes: outside a bracket expression,
4920     a <literal>\</> followed by an alphanumeric character merely stands for
4921     that character as an ordinary character, and inside a bracket expression,
4922     <literal>\</> is an ordinary character.
4923     (The latter is the one actual incompatibility between EREs and AREs.)
4924    </para>
4925
4926    <para>
4927     <firstterm>Character-entry escapes</> exist to make it easier to specify
4928     non-printing and other inconvenient characters in REs.  They are
4929     shown in <xref linkend="posix-character-entry-escapes-table">.
4930    </para>
4931
4932    <para>
4933     <firstterm>Class-shorthand escapes</> provide shorthands for certain
4934     commonly-used character classes.  They are
4935     shown in <xref linkend="posix-class-shorthand-escapes-table">.
4936    </para>
4937
4938    <para>
4939     A <firstterm>constraint escape</> is a constraint,
4940     matching the empty string if specific conditions are met,
4941     written as an escape.  They are
4942     shown in <xref linkend="posix-constraint-escapes-table">.
4943    </para>
4944
4945    <para>
4946     A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
4947     same string matched by the previous parenthesized subexpression specified
4948     by the number <replaceable>n</>
4949     (see <xref linkend="posix-constraint-backref-table">).  For example,
4950     <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
4951     but not <literal>bc</> or <literal>cb</>.
4952     The subexpression must entirely precede the back reference in the RE.
4953     Subexpressions are numbered in the order of their leading parentheses.
4954     Non-capturing parentheses do not define subexpressions.
4955    </para>
4956
4957    <table id="posix-character-entry-escapes-table">
4958     <title>Regular Expression Character-entry Escapes</title>
4959
4960     <tgroup cols="2">
4961      <thead>
4962       <row>
4963        <entry>Escape</entry>
4964        <entry>Description</entry>
4965       </row>
4966      </thead>
4967
4968       <tbody>
4969        <row>
4970        <entry> <literal>\a</> </entry>
4971        <entry> alert (bell) character, as in C </entry>
4972        </row>
4973
4974        <row>
4975        <entry> <literal>\b</> </entry>
4976        <entry> backspace, as in C </entry>
4977        </row>
4978
4979        <row>
4980        <entry> <literal>\B</> </entry>
4981        <entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
4982        doubling </entry>
4983        </row>
4984
4985        <row>
4986        <entry> <literal>\c</><replaceable>X</> </entry>
4987        <entry> (where <replaceable>X</> is any character) the character whose
4988        low-order 5 bits are the same as those of
4989        <replaceable>X</>, and whose other bits are all zero </entry>
4990        </row>
4991
4992        <row>
4993        <entry> <literal>\e</> </entry>
4994        <entry> the character whose collating-sequence name
4995        is <literal>ESC</>,
4996        or failing that, the character with octal value <literal>033</> </entry>
4997        </row>
4998
4999        <row>
5000        <entry> <literal>\f</> </entry>
5001        <entry> form feed, as in C </entry>
5002        </row>
5003
5004        <row>
5005        <entry> <literal>\n</> </entry>
5006        <entry> newline, as in C </entry>
5007        </row>
5008
5009        <row>
5010        <entry> <literal>\r</> </entry>
5011        <entry> carriage return, as in C </entry>
5012        </row>
5013
5014        <row>
5015        <entry> <literal>\t</> </entry>
5016        <entry> horizontal tab, as in C </entry>
5017        </row>
5018
5019        <row>
5020        <entry> <literal>\u</><replaceable>wxyz</> </entry>
5021        <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
5022        the character whose hexadecimal value is
5023        <literal>0x</><replaceable>wxyz</>
5024        </entry>
5025        </row>
5026
5027        <row>
5028        <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
5029        <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
5030        digits)
5031        the character whose hexadecimal value is
5032        <literal>0x</><replaceable>stuvwxyz</>
5033        </entry>
5034        </row>
5035
5036        <row>
5037        <entry> <literal>\v</> </entry>
5038        <entry> vertical tab, as in C </entry>
5039        </row>
5040
5041        <row>
5042        <entry> <literal>\x</><replaceable>hhh</> </entry>
5043        <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
5044        digits)
5045        the character whose hexadecimal value is
5046        <literal>0x</><replaceable>hhh</>
5047        (a single character no matter how many hexadecimal digits are used)
5048        </entry>
5049        </row>
5050
5051        <row>
5052        <entry> <literal>\0</> </entry>
5053        <entry> the character whose value is <literal>0</> (the null byte)</entry>
5054        </row>
5055
5056        <row>
5057        <entry> <literal>\</><replaceable>xy</> </entry>
5058        <entry> (where <replaceable>xy</> is exactly two octal digits,
5059        and is not a <firstterm>back reference</>)
5060        the character whose octal value is
5061        <literal>0</><replaceable>xy</> </entry>
5062        </row>
5063
5064        <row>
5065        <entry> <literal>\</><replaceable>xyz</> </entry>
5066        <entry> (where <replaceable>xyz</> is exactly three octal digits,
5067        and is not a <firstterm>back reference</>)
5068        the character whose octal value is
5069        <literal>0</><replaceable>xyz</> </entry>
5070        </row>
5071       </tbody>
5072      </tgroup>
5073     </table>
5074
5075    <para>
5076     Hexadecimal digits are <literal>0</>-<literal>9</>,
5077     <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
5078     Octal digits are <literal>0</>-<literal>7</>.
5079    </para>
5080
5081    <para>
5082     Numeric character-entry escapes specifying values outside the ASCII range
5083     (0-127) have meanings dependent on the database encoding.  When the
5084     encoding is UTF-8, escape values are equivalent to Unicode code points,
5085     for example <literal>\u1234</> means the character <literal>U+1234</>.
5086     For other multibyte encodings, character-entry escapes usually just
5087     specify the concatenation of the byte values for the character.  If the
5088     escape value does not correspond to any legal character in the database
5089     encoding, no error will be raised, but it will never match any data.
5090    </para>
5091
5092    <para>
5093     The character-entry escapes are always taken as ordinary characters.
5094     For example, <literal>\135</> is <literal>]</> in ASCII, but
5095     <literal>\135</> does not terminate a bracket expression.
5096    </para>
5097
5098    <table id="posix-class-shorthand-escapes-table">
5099     <title>Regular Expression Class-shorthand Escapes</title>
5100
5101     <tgroup cols="2">
5102      <thead>
5103       <row>
5104        <entry>Escape</entry>
5105        <entry>Description</entry>
5106       </row>
5107      </thead>
5108
5109       <tbody>
5110        <row>
5111        <entry> <literal>\d</> </entry>
5112        <entry> <literal>[[:digit:]]</> </entry>
5113        </row>
5114
5115        <row>
5116        <entry> <literal>\s</> </entry>
5117        <entry> <literal>[[:space:]]</> </entry>
5118        </row>
5119
5120        <row>
5121        <entry> <literal>\w</> </entry>
5122        <entry> <literal>[[:alnum:]_]</>
5123        (note underscore is included) </entry>
5124        </row>
5125
5126        <row>
5127        <entry> <literal>\D</> </entry>
5128        <entry> <literal>[^[:digit:]]</> </entry>
5129        </row>
5130
5131        <row>
5132        <entry> <literal>\S</> </entry>
5133        <entry> <literal>[^[:space:]]</> </entry>
5134        </row>
5135
5136        <row>
5137        <entry> <literal>\W</> </entry>
5138        <entry> <literal>[^[:alnum:]_]</>
5139        (note underscore is included) </entry>
5140        </row>
5141       </tbody>
5142      </tgroup>
5143     </table>
5144
5145    <para>
5146     Within bracket expressions, <literal>\d</>, <literal>\s</>,
5147     and <literal>\w</> lose their outer brackets,
5148     and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
5149     (So, for example, <literal>[a-c\d]</> is equivalent to
5150     <literal>[a-c[:digit:]]</>.
5151     Also, <literal>[a-c\D]</>, which is equivalent to
5152     <literal>[a-c^[:digit:]]</>, is illegal.)
5153    </para>
5154
5155    <table id="posix-constraint-escapes-table">
5156     <title>Regular Expression Constraint Escapes</title>
5157
5158     <tgroup cols="2">
5159      <thead>
5160       <row>
5161        <entry>Escape</entry>
5162        <entry>Description</entry>
5163       </row>
5164      </thead>
5165
5166       <tbody>
5167        <row>
5168        <entry> <literal>\A</> </entry>
5169        <entry> matches only at the beginning of the string
5170        (see <xref linkend="posix-matching-rules"> for how this differs from
5171        <literal>^</>) </entry>
5172        </row>
5173
5174        <row>
5175        <entry> <literal>\m</> </entry>
5176        <entry> matches only at the beginning of a word </entry>
5177        </row>
5178
5179        <row>
5180        <entry> <literal>\M</> </entry>
5181        <entry> matches only at the end of a word </entry>
5182        </row>
5183
5184        <row>
5185        <entry> <literal>\y</> </entry>
5186        <entry> matches only at the beginning or end of a word </entry>
5187        </row>
5188
5189        <row>
5190        <entry> <literal>\Y</> </entry>
5191        <entry> matches only at a point that is not the beginning or end of a
5192        word </entry>
5193        </row>
5194
5195        <row>
5196        <entry> <literal>\Z</> </entry>
5197        <entry> matches only at the end of the string
5198        (see <xref linkend="posix-matching-rules"> for how this differs from
5199        <literal>$</>) </entry>
5200        </row>
5201       </tbody>
5202      </tgroup>
5203     </table>
5204
5205    <para>
5206     A word is defined as in the specification of
5207     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
5208     Constraint escapes are illegal within bracket expressions.
5209    </para>
5210
5211    <table id="posix-constraint-backref-table">
5212     <title>Regular Expression Back References</title>
5213
5214     <tgroup cols="2">
5215      <thead>
5216       <row>
5217        <entry>Escape</entry>
5218        <entry>Description</entry>
5219       </row>
5220      </thead>
5221
5222       <tbody>
5223        <row>
5224        <entry> <literal>\</><replaceable>m</> </entry>
5225        <entry> (where <replaceable>m</> is a nonzero digit)
5226        a back reference to the <replaceable>m</>'th subexpression </entry>
5227        </row>
5228
5229        <row>
5230        <entry> <literal>\</><replaceable>mnn</> </entry>
5231        <entry> (where <replaceable>m</> is a nonzero digit, and
5232        <replaceable>nn</> is some more digits, and the decimal value
5233        <replaceable>mnn</> is not greater than the number of closing capturing
5234        parentheses seen so far)
5235        a back reference to the <replaceable>mnn</>'th subexpression </entry>
5236        </row>
5237       </tbody>
5238      </tgroup>
5239     </table>
5240
5241    <note>
5242     <para>
5243      There is an inherent ambiguity between octal character-entry
5244      escapes and back references, which is resolved by the following heuristics,
5245      as hinted at above.
5246      A leading zero always indicates an octal escape.
5247      A single non-zero digit, not followed by another digit,
5248      is always taken as a back reference.
5249      A multi-digit sequence not starting with a zero is taken as a back
5250      reference if it comes after a suitable subexpression
5251      (i.e., the number is in the legal range for a back reference),
5252      and otherwise is taken as octal.
5253     </para>
5254    </note>
5255    </sect3>
5256
5257    <sect3 id="posix-metasyntax">
5258     <title>Regular Expression Metasyntax</title>
5259
5260    <para>
5261     In addition to the main syntax described above, there are some special
5262     forms and miscellaneous syntactic facilities available.
5263    </para>
5264
5265    <para>
5266     An RE can begin with one of two special <firstterm>director</> prefixes.
5267     If an RE begins with <literal>***:</>,
5268     the rest of the RE is taken as an ARE.  (This normally has no effect in
5269     <productname>PostgreSQL</>, since REs are assumed to be AREs;
5270     but it does have an effect if ERE or BRE mode had been specified by
5271     the <replaceable>flags</> parameter to a regex function.)
5272     If an RE begins with <literal>***=</>,
5273     the rest of the RE is taken to be a literal string,
5274     with all characters considered ordinary characters.
5275    </para>
5276
5277    <para>
5278     An ARE can begin with <firstterm>embedded options</>:
5279     a sequence <literal>(?</><replaceable>xyz</><literal>)</>
5280     (where <replaceable>xyz</> is one or more alphabetic characters)
5281     specifies options affecting the rest of the RE.
5282     These options override any previously determined options &mdash;
5283     in particular, they can override the case-sensitivity behavior implied by
5284     a regex operator, or the <replaceable>flags</> parameter to a regex
5285     function.
5286     The available option letters are
5287     shown in <xref linkend="posix-embedded-options-table">.
5288     Note that these same option letters are used in the <replaceable>flags</>
5289     parameters of regex functions.
5290    </para>
5291
5292    <table id="posix-embedded-options-table">
5293     <title>ARE Embedded-option Letters</title>
5294
5295     <tgroup cols="2">
5296      <thead>
5297       <row>
5298        <entry>Option</entry>
5299        <entry>Description</entry>
5300       </row>
5301      </thead>
5302
5303       <tbody>
5304        <row>
5305        <entry> <literal>b</> </entry>
5306        <entry> rest of RE is a BRE </entry>
5307        </row>
5308
5309        <row>
5310        <entry> <literal>c</> </entry>
5311        <entry> case-sensitive matching (overrides operator type) </entry>
5312        </row>
5313
5314        <row>
5315        <entry> <literal>e</> </entry>
5316        <entry> rest of RE is an ERE </entry>
5317        </row>
5318
5319        <row>
5320        <entry> <literal>i</> </entry>
5321        <entry> case-insensitive matching (see
5322        <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
5323        </row>
5324
5325        <row>
5326        <entry> <literal>m</> </entry>
5327        <entry> historical synonym for <literal>n</> </entry>
5328        </row>
5329
5330        <row>
5331        <entry> <literal>n</> </entry>
5332        <entry> newline-sensitive matching (see
5333        <xref linkend="posix-matching-rules">) </entry>
5334        </row>
5335
5336        <row>
5337        <entry> <literal>p</> </entry>
5338        <entry> partial newline-sensitive matching (see
5339        <xref linkend="posix-matching-rules">) </entry>
5340        </row>
5341
5342        <row>
5343        <entry> <literal>q</> </entry>
5344        <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
5345        characters </entry>
5346        </row>
5347
5348        <row>
5349        <entry> <literal>s</> </entry>
5350        <entry> non-newline-sensitive matching (default) </entry>
5351        </row>
5352
5353        <row>
5354        <entry> <literal>t</> </entry>
5355        <entry> tight syntax (default; see below) </entry>
5356        </row>
5357
5358        <row>
5359        <entry> <literal>w</> </entry>
5360        <entry> inverse partial newline-sensitive (<quote>weird</>) matching
5361        (see <xref linkend="posix-matching-rules">) </entry>
5362        </row>
5363
5364        <row>
5365        <entry> <literal>x</> </entry>
5366        <entry> expanded syntax (see below) </entry>
5367        </row>
5368       </tbody>
5369      </tgroup>
5370     </table>
5371
5372    <para>
5373     Embedded options take effect at the <literal>)</> terminating the sequence.
5374     They can appear only at the start of an ARE (after the
5375     <literal>***:</> director if any).
5376    </para>
5377
5378    <para>
5379     In addition to the usual (<firstterm>tight</>) RE syntax, in which all
5380     characters are significant, there is an <firstterm>expanded</> syntax,
5381     available by specifying the embedded <literal>x</> option.
5382     In the expanded syntax,
5383     white-space characters in the RE are ignored, as are
5384     all characters between a <literal>#</>
5385     and the following newline (or the end of the RE).  This
5386     permits paragraphing and commenting a complex RE.
5387     There are three exceptions to that basic rule:
5388
5389     <itemizedlist>
5390      <listitem>
5391       <para>
5392        a white-space character or <literal>#</> preceded by <literal>\</> is
5393        retained
5394       </para>
5395      </listitem>
5396      <listitem>
5397       <para>
5398        white space or <literal>#</> within a bracket expression is retained
5399       </para>
5400      </listitem>
5401      <listitem>
5402       <para>
5403        white space and comments cannot appear within multi-character symbols,
5404        such as <literal>(?:</>
5405       </para>
5406      </listitem>
5407     </itemizedlist>
5408
5409     For this purpose, white-space characters are blank, tab, newline, and
5410     any character that belongs to the <replaceable>space</> character class.
5411    </para>
5412
5413    <para>
5414     Finally, in an ARE, outside bracket expressions, the sequence
5415     <literal>(?#</><replaceable>ttt</><literal>)</>
5416     (where <replaceable>ttt</> is any text not containing a <literal>)</>)
5417     is a comment, completely ignored.
5418     Again, this is not allowed between the characters of
5419     multi-character symbols, like <literal>(?:</>.
5420     Such comments are more a historical artifact than a useful facility,
5421     and their use is deprecated; use the expanded syntax instead.
5422    </para>
5423
5424    <para>
5425     <emphasis>None</> of these metasyntax extensions is available if
5426     an initial <literal>***=</> director
5427     has specified that the user's input be treated as a literal string
5428     rather than as an RE.
5429    </para>
5430    </sect3>
5431
5432    <sect3 id="posix-matching-rules">
5433     <title>Regular Expression Matching Rules</title>
5434
5435    <para>
5436     In the event that an RE could match more than one substring of a given
5437     string, the RE matches the one starting earliest in the string.
5438     If the RE could match more than one substring starting at that point,
5439     either the longest possible match or the shortest possible match will
5440     be taken, depending on whether the RE is <firstterm>greedy</> or
5441     <firstterm>non-greedy</>.
5442    </para>
5443
5444    <para>
5445     Whether an RE is greedy or not is determined by the following rules:
5446     <itemizedlist>
5447      <listitem>
5448       <para>
5449        Most atoms, and all constraints, have no greediness attribute (because
5450        they cannot match variable amounts of text anyway).
5451       </para>
5452      </listitem>
5453      <listitem>
5454       <para>
5455        Adding parentheses around an RE does not change its greediness.
5456       </para>
5457      </listitem>
5458      <listitem>
5459       <para>
5460        A quantified atom with a fixed-repetition quantifier
5461        (<literal>{</><replaceable>m</><literal>}</>
5462        or
5463        <literal>{</><replaceable>m</><literal>}?</>)
5464        has the same greediness (possibly none) as the atom itself.
5465       </para>
5466      </listitem>
5467      <listitem>
5468       <para>
5469        A quantified atom with other normal quantifiers (including
5470        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
5471        with <replaceable>m</> equal to <replaceable>n</>)
5472        is greedy (prefers longest match).
5473       </para>
5474      </listitem>
5475      <listitem>
5476       <para>
5477        A quantified atom with a non-greedy quantifier (including
5478        <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
5479        with <replaceable>m</> equal to <replaceable>n</>)
5480        is non-greedy (prefers shortest match).
5481       </para>
5482      </listitem>
5483      <listitem>
5484       <para>
5485        A branch &mdash; that is, an RE that has no top-level
5486        <literal>|</> operator &mdash; has the same greediness as the first
5487        quantified atom in it that has a greediness attribute.
5488       </para>
5489      </listitem>
5490      <listitem>
5491       <para>
5492        An RE consisting of two or more branches connected by the
5493        <literal>|</> operator is always greedy.
5494       </para>
5495      </listitem>
5496     </itemizedlist>
5497    </para>
5498
5499    <para>
5500     The above rules associate greediness attributes not only with individual
5501     quantified atoms, but with branches and entire REs that contain quantified
5502     atoms.  What that means is that the matching is done in such a way that
5503     the branch, or whole RE, matches the longest or shortest possible
5504     substring <emphasis>as a whole</>.  Once the length of the entire match
5505     is determined, the part of it that matches any particular subexpression
5506     is determined on the basis of the greediness attribute of that
5507     subexpression, with subexpressions starting earlier in the RE taking
5508     priority over ones starting later.
5509    </para>
5510
5511    <para>
5512     An example of what this means:
5513 <screen>
5514 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
5515 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
5516 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
5517 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
5518 </screen>
5519     In the first case, the RE as a whole is greedy because <literal>Y*</>
5520     is greedy.  It can match beginning at the <literal>Y</>, and it matches
5521     the longest possible string starting there, i.e., <literal>Y123</>.
5522     The output is the parenthesized part of that, or <literal>123</>.
5523     In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
5524     is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
5525     the shortest possible string starting there, i.e., <literal>Y1</>.
5526     The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
5527     the decision as to the overall match length; so it is forced to match
5528     just <literal>1</>.
5529    </para>
5530
5531    <para>
5532     In short, when an RE contains both greedy and non-greedy subexpressions,
5533     the total match length is either as long as possible or as short as
5534     possible, according to the attribute assigned to the whole RE.  The
5535     attributes assigned to the subexpressions only affect how much of that
5536     match they are allowed to <quote>eat</> relative to each other.
5537    </para>
5538
5539    <para>
5540     The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
5541     can be used to force greediness or non-greediness, respectively,
5542     on a subexpression or a whole RE.
5543     This is useful when you need the whole RE to have a greediness attribute
5544     different from what's deduced from its elements.  As an example,
5545     suppose that we are trying to separate a string containing some digits
5546     into the digits and the parts before and after them.  We might try to
5547     do that like this:
5548 <screen>
5549 SELECT regexp_match('abc01234xyz', '(.*)(\d+)(.*)');
5550 <lineannotation>Result: </lineannotation><computeroutput>{abc0123,4,xyz}</computeroutput>
5551 </screen>
5552     That didn't work: the first <literal>.*</> is greedy so
5553     it <quote>eats</> as much as it can, leaving the <literal>\d+</> to
5554     match at the last possible place, the last digit.  We might try to fix
5555     that by making it non-greedy:
5556 <screen>
5557 SELECT regexp_match('abc01234xyz', '(.*?)(\d+)(.*)');
5558 <lineannotation>Result: </lineannotation><computeroutput>{abc,0,""}</computeroutput>
5559 </screen>
5560     That didn't work either, because now the RE as a whole is non-greedy
5561     and so it ends the overall match as soon as possible.  We can get what
5562     we want by forcing the RE as a whole to be greedy:
5563 <screen>
5564 SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}');
5565 <lineannotation>Result: </lineannotation><computeroutput>{abc,01234,xyz}</computeroutput>
5566 </screen>
5567     Controlling the RE's overall greediness separately from its components'
5568     greediness allows great flexibility in handling variable-length patterns.
5569    </para>
5570
5571    <para>
5572     When deciding what is a longer or shorter match,
5573     match lengths are measured in characters, not collating elements.
5574     An empty string is considered longer than no match at all.
5575     For example:
5576     <literal>bb*</>
5577     matches the three middle characters of <literal>abbbc</>;
5578     <literal>(week|wee)(night|knights)</>
5579     matches all ten characters of <literal>weeknights</>;
5580     when <literal>(.*).*</>
5581     is matched against <literal>abc</> the parenthesized subexpression
5582     matches all three characters; and when
5583     <literal>(a*)*</> is matched against <literal>bc</>
5584     both the whole RE and the parenthesized
5585     subexpression match an empty string.
5586    </para>
5587
5588    <para>
5589     If case-independent matching is specified,
5590     the effect is much as if all case distinctions had vanished from the
5591     alphabet.
5592     When an alphabetic that exists in multiple cases appears as an
5593     ordinary character outside a bracket expression, it is effectively
5594     transformed into a bracket expression containing both cases,
5595     e.g., <literal>x</> becomes <literal>[xX]</>.
5596     When it appears inside a bracket expression, all case counterparts
5597     of it are added to the bracket expression, e.g.,
5598     <literal>[x]</> becomes <literal>[xX]</>
5599     and <literal>[^x]</> becomes <literal>[^xX]</>.
5600    </para>
5601
5602    <para>
5603     If newline-sensitive matching is specified, <literal>.</>
5604     and bracket expressions using <literal>^</>
5605     will never match the newline character
5606     (so that matches will never cross newlines unless the RE
5607     explicitly arranges it)
5608     and <literal>^</> and <literal>$</>
5609     will match the empty string after and before a newline
5610     respectively, in addition to matching at beginning and end of string
5611     respectively.
5612     But the ARE escapes <literal>\A</> and <literal>\Z</>
5613     continue to match beginning or end of string <emphasis>only</>.
5614    </para>
5615
5616    <para>
5617     If partial newline-sensitive matching is specified,
5618     this affects <literal>.</> and bracket expressions
5619     as with newline-sensitive matching, but not <literal>^</>
5620     and <literal>$</>.
5621    </para>
5622
5623    <para>
5624     If inverse partial newline-sensitive matching is specified,
5625     this affects <literal>^</> and <literal>$</>
5626     as with newline-sensitive matching, but not <literal>.</>
5627     and bracket expressions.
5628     This isn't very useful but is provided for symmetry.
5629    </para>
5630    </sect3>
5631
5632    <sect3 id="posix-limits-compatibility">
5633     <title>Limits and Compatibility</title>
5634
5635    <para>
5636     No particular limit is imposed on the length of REs in this
5637     implementation.  However,
5638     programs intended to be highly portable should not employ REs longer
5639     than 256 bytes,
5640     as a POSIX-compliant implementation can refuse to accept such REs.
5641    </para>
5642
5643    <para>
5644     The only feature of AREs that is actually incompatible with
5645     POSIX EREs is that <literal>\</> does not lose its special
5646     significance inside bracket expressions.
5647     All other ARE features use syntax which is illegal or has
5648     undefined or unspecified effects in POSIX EREs;
5649     the <literal>***</> syntax of directors likewise is outside the POSIX
5650     syntax for both BREs and EREs.
5651    </para>
5652
5653    <para>
5654     Many of the ARE extensions are borrowed from Perl, but some have
5655     been changed to clean them up, and a few Perl extensions are not present.
5656     Incompatibilities of note include <literal>\b</>, <literal>\B</>,
5657     the lack of special treatment for a trailing newline,
5658     the addition of complemented bracket expressions to the things
5659     affected by newline-sensitive matching,
5660     the restrictions on parentheses and back references in lookahead/lookbehind
5661     constraints, and the longest/shortest-match (rather than first-match)
5662     matching semantics.
5663    </para>
5664
5665    <para>
5666     Two significant incompatibilities exist between AREs and the ERE syntax
5667     recognized by pre-7.4 releases of <productname>PostgreSQL</>:
5668
5669     <itemizedlist>
5670      <listitem>
5671       <para>
5672        In AREs, <literal>\</> followed by an alphanumeric character is either
5673        an escape or an error, while in previous releases, it was just another
5674        way of writing the alphanumeric.
5675        This should not be much of a problem because there was no reason to
5676        write such a sequence in earlier releases.
5677       </para>
5678      </listitem>
5679      <listitem>
5680       <para>
5681        In AREs, <literal>\</> remains a special character within
5682        <literal>[]</>, so a literal <literal>\</> within a bracket
5683        expression must be written <literal>\\</>.
5684       </para>
5685      </listitem>
5686     </itemizedlist>
5687    </para>
5688    </sect3>
5689
5690    <sect3 id="posix-basic-regexes">
5691     <title>Basic Regular Expressions</title>
5692
5693    <para>
5694     BREs differ from EREs in several respects.
5695     In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
5696     are ordinary characters and there is no equivalent
5697     for their functionality.
5698     The delimiters for bounds are
5699     <literal>\{</> and <literal>\}</>,
5700     with <literal>{</> and <literal>}</>
5701     by themselves ordinary characters.
5702     The parentheses for nested subexpressions are
5703     <literal>\(</> and <literal>\)</>,
5704     with <literal>(</> and <literal>)</> by themselves ordinary characters.
5705     <literal>^</> is an ordinary character except at the beginning of the
5706     RE or the beginning of a parenthesized subexpression,
5707     <literal>$</> is an ordinary character except at the end of the
5708     RE or the end of a parenthesized subexpression,
5709     and <literal>*</> is an ordinary character if it appears at the beginning
5710     of the RE or the beginning of a parenthesized subexpression
5711     (after a possible leading <literal>^</>).
5712     Finally, single-digit back references are available, and
5713     <literal>\&lt;</> and <literal>\&gt;</>
5714     are synonyms for
5715     <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
5716     respectively; no other escapes are available in BREs.
5717    </para>
5718    </sect3>
5719
5720 <!-- end re_syntax.n man page -->
5721
5722   </sect2>
5723  </sect1>
5724
5725
5726   <sect1 id="functions-formatting">
5727    <title>Data Type Formatting Functions</title>
5728
5729    <indexterm>
5730     <primary>formatting</primary>
5731    </indexterm>
5732
5733    <para>
5734     The <productname>PostgreSQL</productname> formatting functions
5735     provide a powerful set of tools for converting various data types
5736     (date/time, integer, floating point, numeric) to formatted strings
5737     and for converting from formatted strings to specific data types.
5738     <xref linkend="functions-formatting-table"> lists them.
5739     These functions all follow a common calling convention: the first
5740     argument is the value to be formatted and the second argument is a
5741     template that defines the output or input format.
5742    </para>
5743
5744     <table id="functions-formatting-table">
5745      <title>Formatting Functions</title>
5746      <tgroup cols="4">
5747       <thead>
5748        <row>
5749         <entry>Function</entry>
5750         <entry>Return Type</entry>
5751         <entry>Description</entry>
5752         <entry>Example</entry>
5753        </row>
5754       </thead>
5755       <tbody>
5756        <row>
5757         <entry>
5758          <indexterm>
5759           <primary>to_char</primary>
5760          </indexterm>
5761          <literal><function>to_char(<type>timestamp</type>, <type>text</type>)</function></literal>
5762         </entry>
5763         <entry><type>text</type></entry>
5764         <entry>convert time stamp to string</entry>
5765         <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
5766        </row>
5767        <row>
5768         <entry><literal><function>to_char(<type>interval</type>, <type>text</type>)</function></literal></entry>
5769         <entry><type>text</type></entry>
5770         <entry>convert interval to string</entry>
5771         <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
5772        </row>
5773        <row>
5774         <entry><literal><function>to_char(<type>int</type>, <type>text</type>)</function></literal></entry>
5775         <entry><type>text</type></entry>
5776         <entry>convert integer to string</entry>
5777         <entry><literal>to_char(125, '999')</literal></entry>
5778        </row>
5779        <row>
5780         <entry><literal><function>to_char</function>(<type>double precision</type>,
5781         <type>text</type>)</literal></entry>
5782         <entry><type>text</type></entry>
5783         <entry>convert real/double precision to string</entry>
5784         <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
5785        </row>
5786        <row>
5787         <entry><literal><function>to_char(<type>numeric</type>, <type>text</type>)</function></literal></entry>
5788         <entry><type>text</type></entry>
5789         <entry>convert numeric to string</entry>
5790         <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
5791        </row>
5792        <row>
5793         <entry>
5794          <indexterm>
5795           <primary>to_date</primary>
5796          </indexterm>
5797          <literal><function>to_date(<type>text</type>, <type>text</type>)</function></literal>
5798         </entry>
5799         <entry><type>date</type></entry>
5800         <entry>convert string to date</entry>
5801         <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5802        </row>
5803        <row>
5804         <entry>
5805          <indexterm>
5806           <primary>to_number</primary>
5807          </indexterm>
5808          <literal><function>to_number(<type>text</type>, <type>text</type>)</function></literal>
5809         </entry>
5810         <entry><type>numeric</type></entry>
5811         <entry>convert string to numeric</entry>
5812         <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
5813        </row>
5814        <row>
5815         <entry>
5816          <indexterm>
5817           <primary>to_timestamp</primary>
5818          </indexterm>
5819          <literal><function>to_timestamp(<type>text</type>, <type>text</type>)</function></literal>
5820         </entry>
5821         <entry><type>timestamp with time zone</type></entry>
5822         <entry>convert string to time stamp</entry>
5823         <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
5824        </row>
5825       </tbody>
5826      </tgroup>
5827     </table>
5828
5829    <note>
5830     <para>
5831      There is also a single-argument <function>to_timestamp</function>
5832      function; see <xref linkend="functions-datetime-table">.
5833     </para>
5834    </note>
5835
5836    <tip>
5837     <para>
5838      <function>to_timestamp</function> and <function>to_date</function>
5839      exist to handle input formats that cannot be converted by
5840      simple casting.  For most standard date/time formats, simply casting the
5841      source string to the required data type works, and is much easier.
5842      Similarly, <function>to_number</> is unnecessary for standard numeric
5843      representations.
5844     </para>
5845    </tip>
5846
5847    <para>
5848     In a <function>to_char</> output template string, there are certain
5849     patterns that are recognized and replaced with appropriately-formatted
5850     data based on the given value.  Any text that is not a template pattern is
5851     simply copied verbatim.  Similarly, in an input template string (for the
5852     other functions), template patterns identify the values to be supplied by
5853     the input data string.
5854    </para>
5855
5856   <para>
5857    <xref linkend="functions-formatting-datetime-table"> shows the
5858    template patterns available for formatting date and time values.
5859   </para>
5860
5861     <table id="functions-formatting-datetime-table">
5862      <title>Template Patterns for Date/Time Formatting</title>
5863      <tgroup cols="2">
5864       <thead>
5865        <row>
5866         <entry>Pattern</entry>
5867         <entry>Description</entry>
5868        </row>
5869       </thead>
5870       <tbody>
5871        <row>
5872         <entry><literal>HH</literal></entry>
5873         <entry>hour of day (01-12)</entry>
5874        </row>
5875        <row>
5876         <entry><literal>HH12</literal></entry>
5877         <entry>hour of day (01-12)</entry>
5878        </row>
5879        <row>
5880         <entry><literal>HH24</literal></entry>
5881         <entry>hour of day (00-23)</entry>
5882        </row>
5883        <row>
5884         <entry><literal>MI</literal></entry>
5885         <entry>minute (00-59)</entry>
5886        </row>
5887        <row>
5888         <entry><literal>SS</literal></entry>
5889         <entry>second (00-59)</entry>
5890        </row>
5891        <row>
5892         <entry><literal>MS</literal></entry>
5893         <entry>millisecond (000-999)</entry>
5894        </row>
5895        <row>
5896         <entry><literal>US</literal></entry>
5897         <entry>microsecond (000000-999999)</entry>
5898        </row>
5899        <row>
5900         <entry><literal>SSSS</literal></entry>
5901         <entry>seconds past midnight (0-86399)</entry>
5902        </row>
5903        <row>
5904         <entry><literal>AM</literal>, <literal>am</literal>,
5905         <literal>PM</literal> or <literal>pm</literal></entry>
5906         <entry>meridiem indicator (without periods)</entry>
5907        </row>
5908        <row>
5909         <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
5910         <literal>P.M.</literal> or <literal>p.m.</literal></entry>
5911         <entry>meridiem indicator (with periods)</entry>
5912        </row>
5913        <row>
5914         <entry><literal>Y,YYY</literal></entry>
5915         <entry>year (4 or more digits) with comma</entry>
5916        </row>
5917        <row>
5918         <entry><literal>YYYY</literal></entry>
5919         <entry>year (4 or more digits)</entry>
5920        </row>
5921        <row>
5922         <entry><literal>YYY</literal></entry>
5923         <entry>last 3 digits of year</entry>
5924        </row>
5925        <row>
5926         <entry><literal>YY</literal></entry>
5927         <entry>last 2 digits of year</entry>
5928        </row>
5929        <row>
5930         <entry><literal>Y</literal></entry>
5931         <entry>last digit of year</entry>
5932        </row>
5933        <row>
5934         <entry><literal>IYYY</literal></entry>
5935         <entry>ISO 8601 week-numbering year (4 or more digits)</entry>
5936        </row>
5937        <row>
5938         <entry><literal>IYY</literal></entry>
5939         <entry>last 3 digits of ISO 8601 week-numbering year</entry>
5940        </row>
5941        <row>
5942         <entry><literal>IY</literal></entry>
5943         <entry>last 2 digits of ISO 8601 week-numbering year</entry>
5944        </row>
5945        <row>
5946         <entry><literal>I</literal></entry>
5947         <entry>last digit of ISO 8601 week-numbering year</entry>
5948        </row>
5949        <row>
5950         <entry><literal>BC</literal>, <literal>bc</literal>,
5951         <literal>AD</literal> or <literal>ad</literal></entry>
5952         <entry>era indicator (without periods)</entry>
5953        </row>
5954        <row>
5955         <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
5956         <literal>A.D.</literal> or <literal>a.d.</literal></entry>
5957         <entry>era indicator (with periods)</entry>
5958        </row>
5959        <row>
5960         <entry><literal>MONTH</literal></entry>
5961         <entry>full upper case month name (blank-padded to 9 chars)</entry>
5962        </row>
5963        <row>
5964         <entry><literal>Month</literal></entry>
5965         <entry>full capitalized month name (blank-padded to 9 chars)</entry>
5966        </row>
5967        <row>
5968         <entry><literal>month</literal></entry>
5969         <entry>full lower case month name (blank-padded to 9 chars)</entry>
5970        </row>
5971        <row>
5972         <entry><literal>MON</literal></entry>
5973         <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
5974        </row>
5975        <row>
5976         <entry><literal>Mon</literal></entry>
5977         <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
5978        </row>
5979        <row>
5980         <entry><literal>mon</literal></entry>
5981         <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
5982        </row>
5983        <row>
5984         <entry><literal>MM</literal></entry>
5985         <entry>month number (01-12)</entry>
5986        </row>
5987        <row>
5988         <entry><literal>DAY</literal></entry>
5989         <entry>full upper case day name (blank-padded to 9 chars)</entry>
5990        </row>
5991        <row>
5992         <entry><literal>Day</literal></entry>
5993         <entry>full capitalized day name (blank-padded to 9 chars)</entry>
5994        </row>
5995        <row>
5996         <entry><literal>day</literal></entry>
5997         <entry>full lower case day name (blank-padded to 9 chars)</entry>
5998        </row>
5999        <row>
6000         <entry><literal>DY</literal></entry>
6001         <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
6002        </row>
6003        <row>
6004         <entry><literal>Dy</literal></entry>
6005         <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
6006        </row>
6007        <row>
6008         <entry><literal>dy</literal></entry>
6009         <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
6010        </row>
6011        <row>
6012         <entry><literal>DDD</literal></entry>
6013         <entry>day of year (001-366)</entry>
6014        </row>
6015        <row>
6016         <entry><literal>IDDD</literal></entry>
6017         <entry>day of ISO 8601 week-numbering year (001-371; day 1 of the year is Monday of the first ISO week)</entry>
6018        </row>
6019        <row>
6020         <entry><literal>DD</literal></entry>
6021         <entry>day of month (01-31)</entry>
6022        </row>
6023        <row>
6024         <entry><literal>D</literal></entry>
6025         <entry>day of the week, Sunday (<literal>1</>) to Saturday (<literal>7</>)</entry>
6026        </row>
6027        <row>
6028         <entry><literal>ID</literal></entry>
6029         <entry>ISO 8601 day of the week, Monday (<literal>1</>) to Sunday (<literal>7</>)</entry>
6030        </row>
6031        <row>
6032         <entry><literal>W</literal></entry>
6033         <entry>week of month (1-5) (the first week starts on the first day of the month)</entry>
6034        </row>
6035        <row>
6036         <entry><literal>WW</literal></entry>
6037         <entry>week number of year (1-53) (the first week starts on the first day of the year)</entry>
6038        </row>
6039        <row>
6040         <entry><literal>IW</literal></entry>
6041         <entry>week number of ISO 8601 week-numbering year (01-53; the first Thursday of the year is in week 1)</entry>
6042        </row>
6043        <row>
6044         <entry><literal>CC</literal></entry>
6045         <entry>century (2 digits) (the twenty-first century starts on 2001-01-01)</entry>
6046        </row>
6047        <row>
6048         <entry><literal>J</literal></entry>
6049         <entry>Julian Day (integer days since November 24, 4714 BC at midnight UTC)</entry>
6050        </row>
6051        <row>
6052         <entry><literal>Q</literal></entry>
6053         <entry>quarter</entry>
6054        </row>
6055        <row>
6056         <entry><literal>RM</literal></entry>
6057         <entry>month in upper case Roman numerals (I-XII; I=January)</entry>
6058        </row>
6059        <row>
6060         <entry><literal>rm</literal></entry>
6061         <entry>month in lower case Roman numerals (i-xii; i=January)</entry>
6062        </row>
6063        <row>
6064         <entry><literal>TZ</literal></entry>
6065         <entry>upper case time-zone abbreviation
6066          (only supported in <function>to_char</>)</entry>
6067        </row>
6068        <row>
6069         <entry><literal>tz</literal></entry>
6070         <entry>lower case time-zone abbreviation
6071          (only supported in <function>to_char</>)</entry>
6072        </row>
6073        <row>
6074         <entry><literal>OF</literal></entry>
6075         <entry>time-zone offset from UTC
6076          (only supported in <function>to_char</>)</entry>
6077        </row>
6078       </tbody>
6079      </tgroup>
6080     </table>
6081
6082    <para>
6083     Modifiers can be applied to any template pattern to alter its
6084     behavior.  For example, <literal>FMMonth</literal>
6085     is the <literal>Month</literal> pattern with the
6086     <literal>FM</literal> modifier.
6087     <xref linkend="functions-formatting-datetimemod-table"> shows the
6088     modifier patterns for date/time formatting.
6089    </para>
6090
6091     <table id="functions-formatting-datetimemod-table">
6092      <title>Template Pattern Modifiers for Date/Time Formatting</title>
6093      <tgroup cols="3">
6094       <thead>
6095        <row>
6096         <entry>Modifier</entry>
6097         <entry>Description</entry>
6098         <entry>Example</entry>
6099        </row>
6100       </thead>
6101       <tbody>
6102        <row>
6103         <entry><literal>FM</literal> prefix</entry>
6104         <entry>fill mode (suppress leading zeroes and padding blanks)</entry>
6105         <entry><literal>FMMonth</literal></entry>
6106        </row>
6107        <row>
6108         <entry><literal>TH</literal> suffix</entry>
6109         <entry>upper case ordinal number suffix</entry>
6110         <entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
6111        </row>
6112        <row>
6113         <entry><literal>th</literal> suffix</entry>
6114         <entry>lower case ordinal number suffix</entry>
6115         <entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
6116        </row>
6117        <row>
6118         <entry><literal>FX</literal> prefix</entry>
6119         <entry>fixed format global option (see usage notes)</entry>
6120         <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
6121        </row>
6122        <row>
6123         <entry><literal>TM</literal> prefix</entry>
6124         <entry>translation mode (print localized day and month names based on
6125          <xref linkend="guc-lc-time">)</entry>
6126         <entry><literal>TMMonth</literal></entry>
6127        </row>
6128        <row>
6129         <entry><literal>SP</literal> suffix</entry>
6130         <entry>spell mode (not implemented)</entry>
6131         <entry><literal>DDSP</literal></entry>
6132        </row>
6133       </tbody>
6134      </tgroup>
6135     </table>
6136
6137    <para>
6138     Usage notes for date/time formatting:
6139
6140     <itemizedlist>
6141      <listitem>
6142       <para>
6143        <literal>FM</literal> suppresses leading zeroes and trailing blanks
6144        that would otherwise be added to make the output of a pattern be
6145        fixed-width.  In <productname>PostgreSQL</productname>,
6146        <literal>FM</literal> modifies only the next specification, while in
6147        Oracle <literal>FM</literal> affects all subsequent
6148        specifications, and repeated <literal>FM</literal> modifiers
6149        toggle fill mode on and off.
6150       </para>
6151      </listitem>
6152
6153      <listitem>
6154       <para>
6155        <literal>TM</literal> does not include trailing blanks.
6156        <function>to_timestamp</> and <function>to_date</> ignore
6157        the <literal>TM</literal> modifier.
6158       </para>
6159      </listitem>
6160
6161      <listitem>
6162       <para>
6163        <function>to_timestamp</function> and <function>to_date</function>
6164        skip multiple blank spaces in the input string unless the
6165        <literal>FX</literal> option is used. For example,
6166        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> works, but
6167        <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
6168        because <function>to_timestamp</function> expects one space only.
6169        <literal>FX</literal> must be specified as the first item in
6170        the template.
6171       </para>
6172      </listitem>
6173
6174      <listitem>
6175       <para>
6176        Ordinary text is allowed in <function>to_char</function>
6177        templates and will be output literally.  You can put a substring
6178        in double quotes to force it to be interpreted as literal text
6179        even if it contains pattern key words.  For example, in
6180        <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
6181        will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
6182        will not be.  In <function>to_date</>, <function>to_number</>,
6183        and <function>to_timestamp</>, double-quoted strings skip the number of
6184        input characters contained in the string, e.g. <literal>"XX"</>
6185        skips two input characters.
6186       </para>
6187      </listitem>
6188
6189      <listitem>
6190       <para>
6191        If you want to have a double quote in the output you must
6192        precede it with a backslash, for example <literal>'\"YYYY
6193        Month\"'</literal>. <!-- "" font-lock sanity :-) -->
6194       </para>
6195      </listitem>
6196
6197      <listitem>
6198       <para>
6199        In <function>to_timestamp</function> and <function>to_date</function>,
6200        if the year format specification is less than four digits, e.g.
6201        <literal>YYY</>, and the supplied year is less than four digits,
6202        the year will be adjusted to be nearest to the year 2020, e.g.
6203        <literal>95</> becomes 1995.
6204       </para>
6205      </listitem>
6206
6207      <listitem>
6208       <para>
6209        In <function>to_timestamp</function> and <function>to_date</function>,
6210        the <literal>YYYY</literal> conversion has a restriction when
6211        processing years with more than 4 digits. You must
6212        use some non-digit character or template after <literal>YYYY</literal>,
6213        otherwise the year is always interpreted as 4 digits. For example
6214        (with the year 20000):
6215        <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
6216        interpreted as a 4-digit year; instead use a non-digit
6217        separator after the year, like
6218        <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
6219        <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
6220       </para>
6221      </listitem>
6222
6223      <listitem>
6224       <para>
6225        In <function>to_timestamp</function> and <function>to_date</function>,
6226        the <literal>CC</literal> (century) field is accepted but ignored
6227        if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
6228        <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
6229        <literal>YY</literal> or <literal>Y</literal> then the result is
6230        computed as that year in the specified century.  If the century is
6231        specified but the year is not, the first year of the century
6232        is assumed.
6233       </para>
6234      </listitem>
6235
6236      <listitem>
6237       <para>
6238        In <function>to_timestamp</function> and <function>to_date</function>,
6239        weekday names or numbers (<literal>DAY</literal>, <literal>D</literal>,
6240        and related field types) are accepted but are ignored for purposes of
6241        computing the result.  The same is true for quarter
6242        (<literal>Q</literal>) fields.
6243       </para>
6244      </listitem>
6245
6246      <listitem>
6247       <para>
6248        In <function>to_timestamp</function> and <function>to_date</function>,
6249        an ISO 8601 week-numbering date (as distinct from a Gregorian date)
6250        can be specified in one of two ways:
6251        <itemizedlist>
6252         <listitem>
6253          <para>
6254           Year, week number, and weekday:  for
6255           example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal>
6256           returns the date <literal>2006-10-19</literal>.
6257           If you omit the weekday it is assumed to be 1 (Monday).
6258          </para>
6259         </listitem>
6260         <listitem>
6261          <para>
6262           Year and day of year:  for example <literal>to_date('2006-291',
6263           'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
6264          </para>
6265         </listitem>
6266        </itemizedlist>
6267       </para>
6268       <para>
6269        Attempting to enter a date using a mixture of ISO 8601 week-numbering
6270        fields and Gregorian date fields is nonsensical, and will cause an
6271        error.  In the context of an ISO 8601 week-numbering year, the
6272        concept of a <quote>month</> or <quote>day of month</> has no
6273        meaning.  In the context of a Gregorian year, the ISO week has no
6274        meaning.
6275       </para>
6276       <caution>
6277        <para>
6278         While <function>to_date</function> will reject a mixture of
6279         Gregorian and ISO week-numbering date
6280         fields, <function>to_char</function> will not, since output format
6281         specifications like <literal>YYYY-MM-DD (IYYY-IDDD)</> can be
6282         useful.  But avoid writing something like <literal>IYYY-MM-DD</>;
6283         that would yield surprising results near the start of the year.
6284         (See <xref linkend="functions-datetime-extract"> for more
6285         information.)
6286        </para>
6287       </caution>
6288      </listitem>
6289
6290      <listitem>
6291       <para>
6292        In <function>to_timestamp</function>, millisecond
6293        (<literal>MS</literal>) or microsecond (<literal>US</literal>)
6294        fields are used as the
6295        seconds digits after the decimal point. For example
6296        <literal>to_timestamp('12.3', 'SS.MS')</literal> is not 3 milliseconds,
6297        but 300, because the conversion treats it as 12 + 0.3 seconds.
6298        So, for the format <literal>SS.MS</literal>, the input values
6299        <literal>12.3</literal>, <literal>12.30</literal>,
6300        and <literal>12.300</literal> specify the
6301        same number of milliseconds. To get three milliseconds, one must write
6302        <literal>12.003</literal>, which the conversion treats as
6303        12 + 0.003 = 12.003 seconds.
6304       </para>
6305
6306       <para>
6307        Here is a more
6308        complex example:
6309        <literal>to_timestamp('15:12:02.020.001230', 'HH24:MI:SS.MS.US')</literal>
6310        is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
6311        1230 microseconds = 2.021230 seconds.
6312       </para>
6313      </listitem>
6314
6315      <listitem>
6316       <para>
6317         <function>to_char(..., 'ID')</function>'s day of the week numbering
6318         matches the <function>extract(isodow from ...)</function> function, but
6319         <function>to_char(..., 'D')</function>'s does not match
6320         <function>extract(dow from ...)</function>'s day numbering.
6321       </para>
6322      </listitem>
6323
6324      <listitem>
6325       <para>
6326         <function>to_char(interval)</function> formats <literal>HH</> and
6327         <literal>HH12</> as shown on a 12-hour clock, for example zero hours
6328         and 36 hours both output as <literal>12</>, while <literal>HH24</>
6329         outputs the full hour value, which can exceed 23 in
6330         an <type>interval</> value.
6331       </para>
6332      </listitem>
6333
6334     </itemizedlist>
6335    </para>
6336
6337   <para>
6338    <xref linkend="functions-formatting-numeric-table"> shows the
6339    template patterns available for formatting numeric values.
6340   </para>
6341
6342     <table id="functions-formatting-numeric-table">
6343      <title>Template Patterns for Numeric Formatting</title>
6344      <tgroup cols="2">
6345       <thead>
6346        <row>
6347         <entry>Pattern</entry>
6348         <entry>Description</entry>
6349        </row>
6350       </thead>
6351       <tbody>
6352        <row>
6353         <entry><literal>9</literal></entry>
6354         <entry>value with the specified number of digits</entry>
6355        </row>
6356        <row>
6357         <entry><literal>0</literal></entry>
6358         <entry>value with leading zeros</entry>
6359        </row>
6360        <row>
6361         <entry><literal>.</literal> (period)</entry>
6362         <entry>decimal point</entry>
6363        </row>
6364        <row>
6365         <entry><literal>,</literal> (comma)</entry>
6366         <entry>group (thousand) separator</entry>
6367        </row>
6368        <row>
6369         <entry><literal>PR</literal></entry>
6370         <entry>negative value in angle brackets</entry>
6371        </row>
6372        <row>
6373         <entry><literal>S</literal></entry>
6374         <entry>sign anchored to number (uses locale)</entry>
6375        </row>
6376        <row>
6377         <entry><literal>L</literal></entry>
6378         <entry>currency symbol (uses locale)</entry>
6379        </row>
6380        <row>
6381         <entry><literal>D</literal></entry>
6382         <entry>decimal point (uses locale)</entry>
6383        </row>
6384        <row>
6385         <entry><literal>G</literal></entry>
6386         <entry>group separator (uses locale)</entry>
6387        </row>
6388        <row>
6389         <entry><literal>MI</literal></entry>
6390         <entry>minus sign in specified position (if number &lt; 0)</entry>
6391        </row>
6392        <row>
6393         <entry><literal>PL</literal></entry>
6394         <entry>plus sign in specified position (if number &gt; 0)</entry>
6395        </row>
6396        <row>
6397         <entry><literal>SG</literal></entry>
6398         <entry>plus/minus sign in specified position</entry>
6399        </row>
6400        <row>
6401         <entry><literal>RN</literal></entry>
6402         <entry>Roman numeral (input between 1 and 3999)</entry>
6403        </row>
6404        <row>
6405         <entry><literal>TH</literal> or <literal>th</literal></entry>
6406         <entry>ordinal number suffix</entry>
6407        </row>
6408        <row>
6409         <entry><literal>V</literal></entry>
6410         <entry>shift specified number of digits (see notes)</entry>
6411        </row>
6412        <row>
6413         <entry><literal>EEEE</literal></entry>
6414         <entry>exponent for scientific notation</entry>
6415        </row>
6416       </tbody>
6417      </tgroup>
6418     </table>
6419
6420    <para>
6421     Usage notes for numeric formatting:
6422
6423     <itemizedlist>
6424      <listitem>
6425       <para>
6426        A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
6427        <literal>MI</literal> is not anchored to
6428        the number; for example,
6429        <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
6430        but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
6431        The Oracle implementation does not allow the use of
6432        <literal>MI</literal> before <literal>9</literal>, but rather
6433        requires that <literal>9</literal> precede
6434        <literal>MI</literal>.
6435       </para>
6436      </listitem>
6437
6438      <listitem>
6439       <para>
6440        <literal>9</literal> results in a value with the same number of
6441        digits as there are <literal>9</literal>s. If a digit is
6442        not available it outputs a space.
6443       </para>
6444      </listitem>
6445
6446      <listitem>
6447       <para>
6448        <literal>TH</literal> does not convert values less than zero
6449        and does not convert fractional numbers.
6450       </para>
6451      </listitem>
6452
6453      <listitem>
6454       <para>
6455        <literal>PL</literal>, <literal>SG</literal>, and
6456        <literal>TH</literal> are <productname>PostgreSQL</productname>
6457        extensions.
6458       </para>
6459      </listitem>
6460
6461      <listitem>
6462       <para>
6463        <literal>V</literal> with <function>to_char</function>
6464        multiplies the input values by
6465        <literal>10^<replaceable>n</replaceable></literal>, where
6466        <replaceable>n</replaceable> is the number of digits following
6467        <literal>V</literal>.  <literal>V</literal> with
6468        <function>to_number</function> divides in a similar manner.
6469        <function>to_char</function> and <function>to_number</function>
6470        do not support the use of
6471        <literal>V</literal> combined with a decimal point
6472        (e.g., <literal>99.9V99</literal> is not allowed).
6473       </para>
6474      </listitem>
6475
6476      <listitem>
6477       <para>
6478        <literal>EEEE</literal> (scientific notation) cannot be used in
6479        combination with any of the other formatting patterns or
6480        modifiers other than digit and decimal point patterns, and must be at the end of the format string
6481        (e.g., <literal>9.99EEEE</literal> is a valid pattern).
6482       </para>
6483      </listitem>
6484     </itemizedlist>
6485    </para>
6486
6487    <para>
6488     Certain modifiers can be applied to any template pattern to alter its
6489     behavior.  For example, <literal>FM9999</literal>
6490     is the <literal>9999</literal> pattern with the
6491     <literal>FM</literal> modifier.
6492     <xref linkend="functions-formatting-numericmod-table"> shows the
6493     modifier patterns for numeric formatting.
6494    </para>
6495
6496     <table id="functions-formatting-numericmod-table">
6497      <title>Template Pattern Modifiers for Numeric Formatting</title>
6498      <tgroup cols="3">
6499       <thead>
6500        <row>
6501         <entry>Modifier</entry>
6502         <entry>Description</entry>
6503         <entry>Example</entry>
6504        </row>
6505       </thead>
6506       <tbody>
6507        <row>
6508         <entry><literal>FM</literal> prefix</entry>
6509         <entry>fill mode (suppress leading zeroes and padding blanks)</entry>
6510         <entry><literal>FM9999</literal></entry>
6511        </row>
6512        <row>
6513         <entry><literal>TH</literal> suffix</entry>
6514         <entry>upper case ordinal number suffix</entry>
6515         <entry><literal>999TH</literal></entry>
6516        </row>
6517        <row>
6518         <entry><literal>th</literal> suffix</entry>
6519         <entry>lower case ordinal number suffix</entry>
6520         <entry><literal>999th</literal></entry>
6521        </row>
6522       </tbody>
6523      </tgroup>
6524     </table>
6525
6526   <para>
6527    <xref linkend="functions-formatting-examples-table"> shows some
6528    examples of the use of the <function>to_char</function> function.
6529   </para>
6530
6531     <table id="functions-formatting-examples-table">
6532      <title><function>to_char</function> Examples</title>
6533      <tgroup cols="2">
6534       <thead>
6535        <row>
6536         <entry>Expression</entry>
6537         <entry>Result</entry>
6538        </row>
6539       </thead>
6540       <tbody>
6541        <row>
6542         <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
6543         <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
6544        </row>
6545        <row>
6546         <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
6547         <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
6548        </row>
6549        <row>
6550         <entry><literal>to_char(-0.1, '99.99')</literal></entry>
6551         <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
6552        </row>
6553        <row>
6554         <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
6555         <entry><literal>'-.1'</literal></entry>
6556        </row>
6557        <row>
6558         <entry><literal>to_char(0.1, '0.9')</literal></entry>
6559         <entry><literal>'&nbsp;0.1'</literal></entry>
6560        </row>
6561        <row>
6562         <entry><literal>to_char(12, '9990999.9')</literal></entry>
6563         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
6564        </row>
6565        <row>
6566         <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
6567         <entry><literal>'0012.'</literal></entry>
6568        </row>
6569        <row>
6570         <entry><literal>to_char(485, '999')</literal></entry>
6571         <entry><literal>'&nbsp;485'</literal></entry>
6572        </row>
6573        <row>
6574         <entry><literal>to_char(-485, '999')</literal></entry>
6575         <entry><literal>'-485'</literal></entry>
6576        </row>
6577        <row>
6578         <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
6579         <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
6580        </row>
6581        <row>
6582         <entry><literal>to_char(1485, '9,999')</literal></entry>
6583         <entry><literal>'&nbsp;1,485'</literal></entry>
6584        </row>
6585        <row>
6586         <entry><literal>to_char(1485, '9G999')</literal></entry>
6587         <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
6588        </row>
6589        <row>
6590         <entry><literal>to_char(148.5, '999.999')</literal></entry>
6591         <entry><literal>'&nbsp;148.500'</literal></entry>
6592        </row>
6593        <row>
6594         <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
6595         <entry><literal>'148.5'</literal></entry>
6596        </row>
6597        <row>
6598         <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
6599         <entry><literal>'148.500'</literal></entry>
6600        </row>
6601        <row>
6602         <entry><literal>to_char(148.5, '999D999')</literal></entry>
6603         <entry><literal>'&nbsp;148,500'</literal></entry>
6604        </row>
6605        <row>
6606         <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
6607         <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
6608        </row>
6609        <row>
6610         <entry><literal>to_char(-485, '999S')</literal></entry>
6611         <entry><literal>'485-'</literal></entry>
6612        </row>
6613        <row>
6614         <entry><literal>to_char(-485, '999MI')</literal></entry>
6615         <entry><literal>'485-'</literal></entry>
6616        </row>
6617        <row>
6618         <entry><literal>to_char(485, '999MI')</literal></entry>
6619         <entry><literal>'485&nbsp;'</literal></entry>
6620        </row>
6621        <row>
6622         <entry><literal>to_char(485, 'FM999MI')</literal></entry>
6623         <entry><literal>'485'</literal></entry>
6624        </row>
6625        <row>
6626         <entry><literal>to_char(485, 'PL999')</literal></entry>
6627         <entry><literal>'+485'</literal></entry>
6628        </row>
6629        <row>
6630         <entry><literal>to_char(485, 'SG999')</literal></entry>
6631         <entry><literal>'+485'</literal></entry>
6632        </row>
6633        <row>
6634         <entry><literal>to_char(-485, 'SG999')</literal></entry>
6635         <entry><literal>'-485'</literal></entry>
6636        </row>
6637        <row>
6638         <entry><literal>to_char(-485, '9SG99')</literal></entry>
6639         <entry><literal>'4-85'</literal></entry>
6640        </row>
6641        <row>
6642         <entry><literal>to_char(-485, '999PR')</literal></entry>
6643         <entry><literal>'&lt;485&gt;'</literal></entry>
6644        </row>
6645        <row>
6646         <entry><literal>to_char(485, 'L999')</literal></entry>
6647         <entry><literal>'DM&nbsp;485'</literal></entry>
6648        </row>
6649        <row>
6650         <entry><literal>to_char(485, 'RN')</literal></entry>
6651         <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
6652        </row>
6653        <row>
6654         <entry><literal>to_char(485, 'FMRN')</literal></entry>
6655         <entry><literal>'CDLXXXV'</literal></entry>
6656        </row>
6657        <row>
6658         <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
6659         <entry><literal>'V'</literal></entry>
6660        </row>
6661        <row>
6662         <entry><literal>to_char(482, '999th')</literal></entry>
6663         <entry><literal>'&nbsp;482nd'</literal></entry>
6664        </row>
6665        <row>
6666         <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
6667         <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
6668        </row>
6669        <row>
6670         <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
6671         <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
6672        </row>
6673        <row>
6674         <entry><literal>to_char(12, '99V999')</literal></entry>
6675         <entry><literal>'&nbsp;12000'</literal></entry>
6676        </row>
6677        <row>
6678         <entry><literal>to_char(12.4, '99V999')</literal></entry>
6679         <entry><literal>'&nbsp;12400'</literal></entry>
6680        </row>
6681        <row>
6682         <entry><literal>to_char(12.45, '99V9')</literal></entry>
6683         <entry><literal>'&nbsp;125'</literal></entry>
6684        </row>
6685        <row>
6686         <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
6687         <entry><literal>' 4.86e-04'</literal></entry>
6688        </row>
6689       </tbody>
6690      </tgroup>
6691     </table>
6692
6693   </sect1>
6694
6695
6696   <sect1 id="functions-datetime">
6697    <title>Date/Time Functions and Operators</title>
6698
6699   <para>
6700    <xref linkend="functions-datetime-table"> shows the available
6701    functions for date/time value processing, with details appearing in
6702    the following subsections.  <xref
6703    linkend="operators-datetime-table"> illustrates the behaviors of
6704    the basic arithmetic operators (<literal>+</literal>,
6705    <literal>*</literal>, etc.).  For formatting functions, refer to
6706    <xref linkend="functions-formatting">.  You should be familiar with
6707    the background information on date/time data types from <xref
6708    linkend="datatype-datetime">.
6709   </para>
6710
6711   <para>
6712    All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
6713    inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
6714    with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
6715    For brevity, these variants are not shown separately.  Also, the
6716    <literal>+</> and <literal>*</> operators come in commutative pairs (for
6717    example both date + integer and integer + date); we show only one of each
6718    such pair.
6719   </para>
6720
6721     <table id="operators-datetime-table">
6722      <title>Date/Time Operators</title>
6723
6724      <tgroup cols="3">
6725       <thead>
6726        <row>
6727         <entry>Operator</entry>
6728         <entry>Example</entry>
6729         <entry>Result</entry>
6730        </row>
6731       </thead>
6732
6733       <tbody>
6734        <row>
6735         <entry> <literal>+</literal> </entry>
6736         <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
6737         <entry><literal>date '2001-10-05'</literal></entry>
6738        </row>
6739
6740        <row>
6741         <entry> <literal>+</literal> </entry>
6742         <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
6743         <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
6744        </row>
6745
6746        <row>
6747         <entry> <literal>+</literal> </entry>
6748         <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
6749         <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
6750        </row>
6751
6752        <row>
6753         <entry> <literal>+</literal> </entry>
6754         <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
6755         <entry><literal>interval '1 day 01:00:00'</literal></entry>
6756        </row>
6757
6758        <row>
6759         <entry> <literal>+</literal> </entry>
6760         <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
6761         <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
6762        </row>
6763
6764        <row>
6765         <entry> <literal>+</literal> </entry>
6766         <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
6767         <entry><literal>time '04:00:00'</literal></entry>
6768        </row>
6769
6770        <row>
6771         <entry> <literal>-</literal> </entry>
6772         <entry><literal>- interval '23 hours'</literal></entry>
6773         <entry><literal>interval '-23:00:00'</literal></entry>
6774        </row>
6775
6776        <row>
6777         <entry> <literal>-</literal> </entry>
6778         <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
6779         <entry><literal>integer '3'</literal> (days)</entry>
6780        </row>
6781
6782        <row>
6783         <entry> <literal>-</literal> </entry>
6784         <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
6785         <entry><literal>date '2001-09-24'</literal></entry>
6786        </row>
6787
6788        <row>
6789         <entry> <literal>-</literal> </entry>
6790         <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
6791         <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
6792        </row>
6793
6794        <row>
6795         <entry> <literal>-</literal> </entry>
6796         <entry><literal>time '05:00' - time '03:00'</literal></entry>
6797         <entry><literal>interval '02:00:00'</literal></entry>
6798        </row>
6799
6800        <row>
6801         <entry> <literal>-</literal> </entry>
6802         <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
6803         <entry><literal>time '03:00:00'</literal></entry>
6804        </row>
6805
6806        <row>
6807         <entry> <literal>-</literal> </entry>
6808         <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
6809         <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
6810        </row>
6811
6812        <row>
6813         <entry> <literal>-</literal> </entry>
6814         <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
6815         <entry><literal>interval '1 day -01:00:00'</literal></entry>
6816        </row>
6817
6818        <row>
6819         <entry> <literal>-</literal> </entry>
6820         <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
6821         <entry><literal>interval '1 day 15:00:00'</literal></entry>
6822        </row>
6823
6824        <row>
6825         <entry> <literal>*</literal> </entry>
6826         <entry><literal>900 * interval '1 second'</literal></entry>
6827         <entry><literal>interval '00:15:00'</literal></entry>
6828        </row>
6829
6830        <row>
6831         <entry> <literal>*</literal> </entry>
6832         <entry><literal>21 * interval '1 day'</literal></entry>
6833         <entry><literal>interval '21 days'</literal></entry>
6834        </row>
6835
6836        <row>
6837         <entry> <literal>*</literal> </entry>
6838         <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
6839         <entry><literal>interval '03:30:00'</literal></entry>
6840        </row>
6841
6842        <row>
6843         <entry> <literal>/</literal> </entry>
6844         <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
6845         <entry><literal>interval '00:40:00'</literal></entry>
6846        </row>
6847       </tbody>
6848      </tgroup>
6849     </table>
6850
6851     <table id="functions-datetime-table">
6852      <title>Date/Time Functions</title>
6853      <tgroup cols="5">
6854       <thead>
6855        <row>
6856         <entry>Function</entry>
6857         <entry>Return Type</entry>
6858         <entry>Description</entry>
6859         <entry>Example</entry>
6860         <entry>Result</entry>
6861        </row>
6862       </thead>
6863
6864       <tbody>
6865        <row>
6866         <entry>
6867          <indexterm>
6868           <primary>age</primary>
6869          </indexterm>
6870          <literal><function>age(<type>timestamp</type>, <type>timestamp</type>)</function></literal>
6871         </entry>
6872         <entry><type>interval</type></entry>
6873         <entry>Subtract arguments, producing a <quote>symbolic</> result that
6874         uses years and months, rather than just days</entry>
6875         <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
6876         <entry><literal>43 years 9 mons 27 days</literal></entry>
6877        </row>
6878
6879        <row>
6880         <entry><literal><function>age(<type>timestamp</type>)</function></literal></entry>
6881         <entry><type>interval</type></entry>
6882         <entry>Subtract from <function>current_date</function> (at midnight)</entry>
6883         <entry><literal>age(timestamp '1957-06-13')</literal></entry>
6884         <entry><literal>43 years 8 mons 3 days</literal></entry>
6885        </row>
6886
6887        <row>
6888         <entry>
6889          <indexterm>
6890           <primary>clock_timestamp</primary>
6891          </indexterm>
6892          <literal><function>clock_timestamp()</function></literal>
6893         </entry>
6894         <entry><type>timestamp with time zone</type></entry>
6895         <entry>Current date and time (changes during statement execution);
6896          see <xref linkend="functions-datetime-current">
6897         </entry>
6898         <entry></entry>
6899         <entry></entry>
6900        </row>
6901
6902        <row>
6903         <entry>
6904          <indexterm>
6905           <primary>current_date</primary>
6906          </indexterm>
6907          <literal><function>current_date</function></literal>
6908         </entry>
6909         <entry><type>date</type></entry>
6910         <entry>Current date;
6911          see <xref linkend="functions-datetime-current">
6912         </entry>
6913         <entry></entry>
6914         <entry></entry>
6915        </row>
6916
6917        <row>
6918         <entry>
6919          <indexterm>
6920           <primary>current_time</primary>
6921          </indexterm>
6922          <literal><function>current_time</function></literal>
6923         </entry>
6924         <entry><type>time with time zone</type></entry>
6925         <entry>Current time of day;
6926          see <xref linkend="functions-datetime-current">
6927         </entry>
6928         <entry></entry>
6929         <entry></entry>
6930        </row>
6931
6932        <row>
6933         <entry>
6934          <indexterm>
6935           <primary>current_timestamp</primary>
6936          </indexterm>
6937          <literal><function>current_timestamp</function></literal>
6938         </entry>
6939         <entry><type>timestamp with time zone</type></entry>
6940         <entry>Current date and time (start of current transaction);
6941          see <xref linkend="functions-datetime-current">
6942         </entry>
6943         <entry></entry>
6944         <entry></entry>
6945        </row>
6946
6947        <row>
6948         <entry>
6949          <indexterm>
6950           <primary>date_part</primary>
6951          </indexterm>
6952          <literal><function>date_part(<type>text</type>, <type>timestamp</type>)</function></literal>
6953         </entry>
6954         <entry><type>double precision</type></entry>
6955         <entry>Get subfield (equivalent to <function>extract</function>);
6956          see <xref linkend="functions-datetime-extract">
6957         </entry>
6958         <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6959         <entry><literal>20</literal></entry>
6960        </row>
6961
6962        <row>
6963         <entry><literal><function>date_part(<type>text</type>, <type>interval</type>)</function></literal></entry>
6964         <entry><type>double precision</type></entry>
6965         <entry>Get subfield (equivalent to
6966          <function>extract</function>); see <xref linkend="functions-datetime-extract">
6967         </entry>
6968         <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
6969         <entry><literal>3</literal></entry>
6970        </row>
6971
6972        <row>
6973         <entry>
6974          <indexterm>
6975           <primary>date_trunc</primary>
6976          </indexterm>
6977          <literal><function>date_trunc(<type>text</type>, <type>timestamp</type>)</function></literal>
6978         </entry>
6979         <entry><type>timestamp</type></entry>
6980         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
6981         </entry>
6982         <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
6983         <entry><literal>2001-02-16 20:00:00</literal></entry>
6984        </row>
6985
6986        <row>
6987         <entry><literal><function>date_trunc(<type>text</type>, <type>interval</type>)</function></literal></entry>
6988         <entry><type>interval</type></entry>
6989         <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
6990         </entry>
6991         <entry><literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal></entry>
6992         <entry><literal>2 days 03:00:00</literal></entry>
6993        </row>
6994
6995        <row>
6996         <entry>
6997          <indexterm>
6998           <primary>extract</primary>
6999          </indexterm>
7000          <literal><function>extract</function>(<parameter>field</parameter> from
7001          <type>timestamp</type>)</literal>
7002         </entry>
7003         <entry><type>double precision</type></entry>
7004         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
7005         </entry>
7006         <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
7007         <entry><literal>20</literal></entry>
7008        </row>
7009
7010        <row>
7011         <entry><literal><function>extract</function>(<parameter>field</parameter> from
7012          <type>interval</type>)</literal></entry>
7013         <entry><type>double precision</type></entry>
7014         <entry>Get subfield; see <xref linkend="functions-datetime-extract">
7015         </entry>
7016         <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
7017         <entry><literal>3</literal></entry>
7018        </row>
7019
7020        <row>
7021         <entry>
7022          <indexterm>
7023           <primary>isfinite</primary>
7024          </indexterm>
7025          <literal><function>isfinite(<type>date</type>)</function></literal>
7026         </entry>
7027         <entry><type>boolean</type></entry>
7028         <entry>Test for finite date (not +/-infinity)</entry>
7029         <entry><literal>isfinite(date '2001-02-16')</literal></entry>
7030         <entry><literal>true</literal></entry>
7031        </row>
7032
7033        <row>
7034         <entry><literal><function>isfinite(<type>timestamp</type>)</function></literal></entry>
7035         <entry><type>boolean</type></entry>
7036         <entry>Test for finite time stamp (not +/-infinity)</entry>
7037         <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
7038         <entry><literal>true</literal></entry>
7039        </row>
7040
7041        <row>
7042         <entry><literal><function>isfinite(<type>interval</type>)</function></literal></entry>
7043         <entry><type>boolean</type></entry>
7044         <entry>Test for finite interval</entry>
7045         <entry><literal>isfinite(interval '4 hours')</literal></entry>
7046         <entry><literal>true</literal></entry>
7047        </row>
7048
7049        <row>
7050         <entry>
7051          <indexterm>
7052           <primary>justify_days</primary>
7053          </indexterm>
7054          <literal><function>justify_days(<type>interval</type>)</function></literal>
7055         </entry>
7056         <entry><type>interval</type></entry>
7057         <entry>Adjust interval so 30-day time periods are represented as months</entry>
7058         <entry><literal>justify_days(interval '35 days')</literal></entry>
7059         <entry><literal>1 mon 5 days</literal></entry>
7060        </row>
7061
7062        <row>
7063         <entry>
7064          <indexterm>
7065           <primary>justify_hours</primary>
7066          </indexterm>
7067          <literal><function>justify_hours(<type>interval</type>)</function></literal>
7068         </entry>
7069         <entry><type>interval</type></entry>
7070         <entry>Adjust interval so 24-hour time periods are represented as days</entry>
7071         <entry><literal>justify_hours(interval '27 hours')</literal></entry>
7072         <entry><literal>1 day 03:00:00</literal></entry>
7073        </row>
7074
7075        <row>
7076         <entry>
7077          <indexterm>
7078           <primary>justify_interval</primary>
7079          </indexterm>
7080          <literal><function>justify_interval(<type>interval</type>)</function></literal>
7081         </entry>
7082         <entry><type>interval</type></entry>
7083         <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
7084         <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
7085         <entry><literal>29 days 23:00:00</literal></entry>
7086        </row>
7087
7088        <row>
7089         <entry>
7090          <indexterm>
7091           <primary>localtime</primary>
7092          </indexterm>
7093          <literal><function>localtime</function></literal>
7094         </entry>
7095         <entry><type>time</type></entry>
7096         <entry>Current time of day;
7097          see <xref linkend="functions-datetime-current">
7098         </entry>
7099         <entry></entry>
7100         <entry></entry>
7101        </row>
7102
7103        <row>
7104         <entry>
7105          <indexterm>
7106           <primary>localtimestamp</primary>
7107          </indexterm>
7108          <literal><function>localtimestamp</function></literal>
7109         </entry>
7110         <entry><type>timestamp</type></entry>
7111         <entry>Current date and time (start of current transaction);
7112          see <xref linkend="functions-datetime-current">
7113         </entry>
7114         <entry></entry>
7115         <entry></entry>
7116        </row>
7117
7118        <row>
7119         <entry>
7120          <indexterm>
7121           <primary>make_date</primary>
7122          </indexterm>
7123          <literal>
7124             <function>
7125              make_date(<parameter>year</parameter> <type>int</type>,
7126              <parameter>month</parameter> <type>int</type>,
7127              <parameter>day</parameter> <type>int</type>)
7128             </function>
7129          </literal>
7130         </entry>
7131         <entry><type>date</type></entry>
7132         <entry>
7133          Create date from year, month and day fields
7134         </entry>
7135         <entry><literal>make_date(2013, 7, 15)</literal></entry>
7136         <entry><literal>2013-07-15</literal></entry>
7137        </row>
7138
7139        <row>
7140         <entry>
7141          <indexterm>
7142           <primary>make_interval</primary>
7143          </indexterm>
7144          <literal>
7145           <function>
7146            make_interval(<parameter>years</parameter> <type>int</type> DEFAULT 0,
7147            <parameter>months</parameter> <type>int</type> DEFAULT 0,
7148            <parameter>weeks</parameter> <type>int</type> DEFAULT 0,
7149            <parameter>days</parameter> <type>int</type> DEFAULT 0,
7150            <parameter>hours</parameter> <type>int</type> DEFAULT 0,
7151            <parameter>mins</parameter> <type>int</type> DEFAULT 0,
7152            <parameter>secs</parameter> <type>double precision</type> DEFAULT 0.0)
7153           </function>
7154          </literal>
7155         </entry>
7156         <entry><type>interval</type></entry>
7157         <entry>
7158          Create interval from years, months, weeks, days, hours, minutes and
7159          seconds fields
7160         </entry>
7161         <entry><literal>make_interval(days =&gt; 10)</literal></entry>
7162         <entry><literal>10 days</literal></entry>
7163        </row>
7164
7165        <row>
7166         <entry>
7167          <indexterm>
7168           <primary>make_time</primary>
7169          </indexterm>
7170          <literal>
7171           <function>
7172            make_time(<parameter>hour</parameter> <type>int</type>,
7173            <parameter>min</parameter> <type>int</type>,
7174            <parameter>sec</parameter> <type>double precision</type>)
7175           </function>
7176          </literal>
7177         </entry>
7178         <entry><type>time</type></entry>
7179         <entry>
7180          Create time from hour, minute and seconds fields
7181         </entry>
7182         <entry><literal>make_time(8, 15, 23.5)</literal></entry>
7183         <entry><literal>08:15:23.5</literal></entry>
7184        </row>
7185
7186        <row>
7187         <entry>
7188          <indexterm>
7189           <primary>make_timestamp</primary>
7190          </indexterm>
7191          <literal>
7192           <function>
7193            make_timestamp(<parameter>year</parameter> <type>int</type>,
7194            <parameter>month</parameter> <type>int</type>,
7195            <parameter>day</parameter> <type>int</type>,
7196            <parameter>hour</parameter> <type>int</type>,
7197            <parameter>min</parameter> <type>int</type>,
7198            <parameter>sec</parameter> <type>double precision</type>)
7199           </function>
7200          </literal>
7201         </entry>
7202         <entry><type>timestamp</type></entry>
7203         <entry>
7204          Create timestamp from year, month, day, hour, minute and seconds fields
7205         </entry>
7206         <entry><literal>make_timestamp(2013, 7, 15, 8, 15, 23.5)</literal></entry>
7207         <entry><literal>2013-07-15 08:15:23.5</literal></entry>
7208        </row>
7209
7210        <row>
7211         <entry>
7212          <indexterm>
7213           <primary>make_timestamptz</primary>
7214          </indexterm>
7215          <literal>
7216           <function>
7217            make_timestamptz(<parameter>year</parameter> <type>int</type>,
7218            <parameter>month</parameter> <type>int</type>,
7219            <parameter>day</parameter> <type>int</type>,
7220            <parameter>hour</parameter> <type>int</type>,
7221            <parameter>min</parameter> <type>int</type>,
7222            <parameter>sec</parameter> <type>double precision</type>,
7223            <optional> <parameter>timezone</parameter> <type>text</type> </optional>)
7224           </function>
7225          </literal>
7226         </entry>
7227         <entry><type>timestamp with time zone</type></entry>
7228         <entry>
7229          Create timestamp with time zone from year, month, day, hour, minute
7230          and seconds fields; if <parameter>timezone</parameter> is not
7231          specified, the current time zone is used
7232         </entry>
7233         <entry><literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5)</literal></entry>
7234         <entry><literal>2013-07-15 08:15:23.5+01</literal></entry>
7235        </row>
7236
7237        <row>
7238         <entry>
7239          <indexterm>
7240           <primary>now</primary>
7241          </indexterm>
7242          <literal><function>now()</function></literal>
7243         </entry>
7244         <entry><type>timestamp with time zone</type></entry>
7245         <entry>Current date and time (start of current transaction);
7246          see <xref linkend="functions-datetime-current">
7247         </entry>
7248         <entry></entry>
7249         <entry></entry>
7250        </row>
7251
7252        <row>
7253         <entry>
7254          <indexterm>
7255           <primary>statement_timestamp</primary>
7256          </indexterm>
7257          <literal><function>statement_timestamp()</function></literal>
7258         </entry>
7259         <entry><type>timestamp with time zone</type></entry>
7260         <entry>Current date and time (start of current statement);
7261          see <xref linkend="functions-datetime-current">
7262         </entry>
7263         <entry></entry>
7264         <entry></entry>
7265        </row>
7266
7267        <row>
7268         <entry>
7269          <indexterm>
7270           <primary>timeofday</primary>
7271          </indexterm>
7272          <literal><function>timeofday()</function></literal>
7273         </entry>
7274         <entry><type>text</type></entry>
7275         <entry>Current date and time
7276          (like <function>clock_timestamp</>, but as a <type>text</> string);
7277          see <xref linkend="functions-datetime-current">
7278         </entry>
7279         <entry></entry>
7280         <entry></entry>
7281        </row>
7282
7283        <row>
7284         <entry>
7285          <indexterm>
7286           <primary>transaction_timestamp</primary>
7287          </indexterm>
7288          <literal><function>transaction_timestamp()</function></literal>
7289         </entry>
7290         <entry><type>timestamp with time zone</type></entry>
7291         <entry>Current date and time (start of current transaction);
7292          see <xref linkend="functions-datetime-current">
7293         </entry>
7294         <entry></entry>
7295         <entry></entry>
7296        </row>
7297        <row>
7298         <entry>
7299          <indexterm>
7300           <primary>to_timestamp</primary>
7301          </indexterm>
7302          <literal><function>to_timestamp(<type>double precision</type>)</function></literal>
7303         </entry>
7304         <entry><type>timestamp with time zone</type></entry>
7305         <entry>Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to
7306          timestamp</entry>
7307         <entry><literal>to_timestamp(1284352323)</literal></entry>
7308         <entry><literal>2010-09-13 04:32:03+00</literal></entry>
7309        </row>
7310       </tbody>
7311      </tgroup>
7312     </table>
7313
7314    <para>
7315     <indexterm>
7316       <primary>OVERLAPS</primary>
7317     </indexterm>
7318     In addition to these functions, the SQL <literal>OVERLAPS</> operator is
7319     supported:
7320 <synopsis>
7321 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
7322 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
7323 </synopsis>
7324     This expression yields true when two time periods (defined by their
7325     endpoints) overlap, false when they do not overlap.  The endpoints
7326     can be specified as pairs of dates, times, or time stamps; or as
7327     a date, time, or time stamp followed by an interval.  When a pair
7328     of values is provided, either the start or the end can be written
7329     first; <literal>OVERLAPS</> automatically takes the earlier value
7330     of the pair as the start.  Each time period is considered to
7331     represent the half-open interval <replaceable>start</> <literal>&lt;=</>
7332     <replaceable>time</> <literal>&lt;</> <replaceable>end</>, unless
7333     <replaceable>start</> and <replaceable>end</> are equal in which case it
7334     represents that single time instant.  This means for instance that two
7335     time periods with only an endpoint in common do not overlap.
7336    </para>
7337
7338 <screen>
7339 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
7340        (DATE '2001-10-30', DATE '2002-10-30');
7341 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
7342 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
7343        (DATE '2001-10-30', DATE '2002-10-30');
7344 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
7345 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
7346        (DATE '2001-10-30', DATE '2001-10-31');
7347 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
7348 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
7349        (DATE '2001-10-30', DATE '2001-10-31');
7350 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
7351 </screen>
7352
7353   <para>
7354    When adding an <type>interval</type> value to (or subtracting an
7355    <type>interval</type> value from) a <type>timestamp with time zone</type>
7356    value, the days component advances or decrements the date of the
7357    <type>timestamp with time zone</type> by the indicated number of days.
7358    Across daylight saving time changes (when the session time zone is set to a
7359    time zone that recognizes DST), this means <literal>interval '1 day'</literal>
7360    does not necessarily equal <literal>interval '24 hours'</literal>.
7361    For example, with the session time zone set to <literal>CST7CDT</literal>,
7362    <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day'</literal>
7363    will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>,
7364    while adding <literal>interval '24 hours'</literal> to the same initial
7365    <type>timestamp with time zone</type> produces
7366    <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
7367    a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone
7368    <literal>CST7CDT</literal>.
7369   </para>
7370
7371   <para>
7372    Note there can be ambiguity in the <literal>months</> field returned by
7373    <function>age</> because different months have different numbers of
7374    days.  <productname>PostgreSQL</>'s approach uses the month from the
7375    earlier of the two dates when calculating partial months.  For example,
7376    <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
7377    <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
7378    days</> because May has 31 days, while April has only 30.
7379   </para>
7380
7381   <para>
7382    Subtraction of dates and timestamps can also be complex.  One conceptually
7383    simple way to perform subtraction is to convert each value to a number
7384    of seconds using <literal>EXTRACT(EPOCH FROM ...)</>, then subtract the
7385    results; this produces the
7386    number of <emphasis>seconds</> between the two values.  This will adjust
7387    for the number of days in each month, timezone changes, and daylight
7388    saving time adjustments.  Subtraction of date or timestamp
7389    values with the <quote><literal>-</></quote> operator
7390    returns the number of days (24-hours) and hours/minutes/seconds
7391    between the values, making the same adjustments.  The <function>age</>
7392    function returns years, months, days, and hours/minutes/seconds,
7393    performing field-by-field subtraction and then adjusting for negative
7394    field values.  The following queries illustrate the differences in these
7395    approaches.  The sample results were produced with <literal>timezone
7396    = 'US/Eastern'</>; there is a daylight saving time change between the
7397    two dates used:
7398   </para>
7399
7400 <screen>
7401 SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
7402        EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
7403 <lineannotation>Result: </lineannotation><computeroutput>10537200</computeroutput>
7404 SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
7405         EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
7406         / 60 / 60 / 24;
7407 <lineannotation>Result: </lineannotation><computeroutput>121.958333333333</computeroutput>
7408 SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
7409 <lineannotation>Result: </lineannotation><computeroutput>121 days 23:00:00</computeroutput>
7410 SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00');
7411 <lineannotation>Result: </lineannotation><computeroutput>4 mons</computeroutput>
7412 </screen>
7413
7414   <sect2 id="functions-datetime-extract">
7415    <title><function>EXTRACT</function>, <function>date_part</function></title>
7416
7417    <indexterm>
7418     <primary>date_part</primary>
7419    </indexterm>
7420    <indexterm>
7421     <primary>extract</primary>
7422    </indexterm>
7423
7424 <synopsis>
7425 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
7426 </synopsis>
7427
7428    <para>
7429     The <function>extract</function> function retrieves subfields
7430     such as year or hour from date/time values.
7431     <replaceable>source</replaceable> must be a value expression of
7432     type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
7433     (Expressions of type <type>date</type> are
7434     cast to <type>timestamp</type> and can therefore be used as
7435     well.)  <replaceable>field</replaceable> is an identifier or
7436     string that selects what field to extract from the source value.
7437     The <function>extract</function> function returns values of type
7438     <type>double precision</type>.
7439     The following are valid field names:
7440
7441     <!-- alphabetical -->
7442     <variablelist>
7443      <varlistentry>
7444       <term><literal>century</literal></term>
7445       <listitem>
7446        <para>
7447         The century
7448        </para>
7449
7450 <screen>
7451 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
7452 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
7453 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
7454 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
7455 </screen>
7456
7457        <para>
7458         The first century starts at 0001-01-01 00:00:00 AD, although
7459         they did not know it at the time. This definition applies to all
7460         Gregorian calendar countries. There is no century number 0,
7461         you go from -1 century to 1 century.
7462
7463         If you disagree with this, please write your complaint to:
7464         Pope, Cathedral Saint-Peter of Roma, Vatican.
7465        </para>
7466       </listitem>
7467      </varlistentry>
7468
7469      <varlistentry>
7470       <term><literal>day</literal></term>
7471       <listitem>
7472        <para>
7473         For <type>timestamp</type> values, the day (of the month) field
7474         (1 - 31) ; for <type>interval</type> values, the number of days
7475        </para>
7476
7477 <screen>
7478 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
7479 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
7480
7481 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
7482 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
7483 </screen>
7484
7485
7486
7487       </listitem>
7488      </varlistentry>
7489
7490      <varlistentry>
7491       <term><literal>decade</literal></term>
7492       <listitem>
7493        <para>
7494         The year field divided by 10
7495        </para>
7496
7497 <screen>
7498 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
7499 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
7500 </screen>
7501       </listitem>
7502      </varlistentry>
7503
7504      <varlistentry>
7505       <term><literal>dow</literal></term>
7506       <listitem>
7507        <para>
7508         The day of the week as Sunday (<literal>0</>) to
7509         Saturday (<literal>6</>)
7510        </para>
7511
7512 <screen>
7513 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
7514 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
7515 </screen>
7516        <para>
7517         Note that <function>extract</function>'s day of the week numbering
7518         differs from that of the <function>to_char(...,
7519         'D')</function> function.
7520        </para>
7521
7522       </listitem>
7523      </varlistentry>
7524
7525      <varlistentry>
7526       <term><literal>doy</literal></term>
7527       <listitem>
7528        <para>
7529         The day of the year (1 - 365/366)
7530        </para>
7531
7532 <screen>
7533 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
7534 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
7535 </screen>
7536       </listitem>
7537      </varlistentry>
7538
7539      <varlistentry>
7540       <term><literal>epoch</literal></term>
7541       <listitem>
7542        <para>
7543         For <type>timestamp with time zone</type> values, the
7544         number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
7545         for <type>date</type> and <type>timestamp</type> values, the
7546         number of seconds since 1970-01-01 00:00:00 local time;
7547         for <type>interval</type> values, the total number
7548         of seconds in the interval
7549        </para>
7550
7551 <screen>
7552 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
7553 <lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput>
7554
7555 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
7556 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
7557 </screen>
7558
7559        <para>
7560         You can convert an epoch value back to a time stamp
7561         with <function>to_timestamp</>:
7562        </para>
7563 <screen>
7564 SELECT to_timestamp(982384720.12);
7565 <lineannotation>Result: </lineannotation><computeroutput>2001-02-17 04:38:40.12+00</computeroutput>
7566 </screen>
7567       </listitem>
7568      </varlistentry>
7569
7570      <varlistentry>
7571       <term><literal>hour</literal></term>
7572       <listitem>
7573        <para>
7574         The hour field (0 - 23)
7575        </para>
7576
7577 <screen>
7578 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
7579 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
7580 </screen>
7581       </listitem>
7582      </varlistentry>
7583
7584      <varlistentry>
7585       <term><literal>isodow</literal></term>
7586       <listitem>
7587        <para>
7588         The day of the week as Monday (<literal>1</>) to
7589         Sunday (<literal>7</>)
7590        </para>
7591
7592 <screen>
7593 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
7594 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
7595 </screen>
7596        <para>
7597         This is identical to <literal>dow</> except for Sunday.  This
7598         matches the <acronym>ISO</> 8601 day of the week numbering.
7599        </para>
7600
7601       </listitem>
7602      </varlistentry>
7603
7604      <varlistentry>
7605       <term><literal>isoyear</literal></term>
7606       <listitem>
7607        <para>
7608         The <acronym>ISO</acronym> 8601 week-numbering year that the date
7609         falls in (not applicable to intervals)
7610        </para>
7611
7612 <screen>
7613 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
7614 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
7615 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
7616 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
7617 </screen>
7618
7619        <para>
7620         Each <acronym>ISO</acronym> 8601 week-numbering year begins with the
7621         Monday of the week containing the 4th of January, so in early
7622         January or late December the <acronym>ISO</acronym> year may be
7623         different from the Gregorian year.  See the <literal>week</literal>
7624         field for more information.
7625        </para>
7626        <para>
7627         This field is not available in PostgreSQL releases prior to 8.3.
7628        </para>
7629       </listitem>
7630      </varlistentry>
7631
7632      <varlistentry>
7633       <term><literal>microseconds</literal></term>
7634       <listitem>
7635        <para>
7636         The seconds field, including fractional parts, multiplied by 1
7637         000 000;  note that this includes full seconds
7638        </para>
7639
7640 <screen>
7641 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
7642 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
7643 </screen>
7644       </listitem>
7645      </varlistentry>
7646
7647      <varlistentry>
7648       <term><literal>millennium</literal></term>
7649       <listitem>
7650        <para>
7651         The millennium
7652        </para>
7653
7654 <screen>
7655 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
7656 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
7657 </screen>
7658
7659        <para>
7660         Years in the 1900s are in the second millennium.
7661         The third millennium started January 1, 2001.
7662        </para>
7663       </listitem>
7664      </varlistentry>
7665
7666      <varlistentry>
7667       <term><literal>milliseconds</literal></term>
7668       <listitem>
7669        <para>
7670         The seconds field, including fractional parts, multiplied by
7671         1000.  Note that this includes full seconds.
7672        </para>
7673
7674 <screen>
7675 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
7676 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
7677 </screen>
7678       </listitem>
7679      </varlistentry>
7680
7681      <varlistentry>
7682       <term><literal>minute</literal></term>
7683       <listitem>
7684        <para>
7685         The minutes field (0 - 59)
7686        </para>
7687
7688 <screen>
7689 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
7690 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
7691 </screen>
7692       </listitem>
7693      </varlistentry>
7694
7695      <varlistentry>
7696       <term><literal>month</literal></term>
7697       <listitem>
7698        <para>
7699         For <type>timestamp</type> values, the number of the month
7700         within the year (1 - 12) ; for <type>interval</type> values,
7701         the number of months, modulo 12 (0 - 11)
7702        </para>
7703
7704 <screen>
7705 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
7706 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
7707
7708 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
7709 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
7710
7711 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
7712 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7713 </screen>
7714       </listitem>
7715      </varlistentry>
7716
7717      <varlistentry>
7718       <term><literal>quarter</literal></term>
7719       <listitem>
7720        <para>
7721         The quarter of the year (1 - 4) that the date is in
7722        </para>
7723
7724 <screen>
7725 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
7726 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7727 </screen>
7728       </listitem>
7729      </varlistentry>
7730
7731      <varlistentry>
7732       <term><literal>second</literal></term>
7733       <listitem>
7734        <para>
7735         The seconds field, including fractional parts (0 -
7736         59<footnote><simpara>60 if leap seconds are
7737         implemented by the operating system</simpara></footnote>)
7738        </para>
7739
7740 <screen>
7741 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
7742 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
7743
7744 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
7745 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
7746 </screen>
7747       </listitem>
7748      </varlistentry>
7749      <varlistentry>
7750       <term><literal>timezone</literal></term>
7751       <listitem>
7752        <para>
7753         The time zone offset from UTC, measured in seconds.  Positive values
7754         correspond to time zones east of UTC, negative values to
7755         zones west of UTC.  (Technically,
7756         <productname>PostgreSQL</productname> does not use UTC because
7757         leap seconds are not handled.)
7758        </para>
7759       </listitem>
7760      </varlistentry>
7761
7762      <varlistentry>
7763       <term><literal>timezone_hour</literal></term>
7764       <listitem>
7765        <para>
7766         The hour component of the time zone offset
7767        </para>
7768       </listitem>
7769      </varlistentry>
7770
7771      <varlistentry>
7772       <term><literal>timezone_minute</literal></term>
7773       <listitem>
7774        <para>
7775         The minute component of the time zone offset
7776        </para>
7777       </listitem>
7778      </varlistentry>
7779
7780      <varlistentry>
7781       <term><literal>week</literal></term>
7782       <listitem>
7783        <para>
7784         The number of the <acronym>ISO</acronym> 8601 week-numbering week of
7785         the year.  By definition, ISO weeks start on Mondays and the first
7786         week of a year contains January 4 of that year.  In other words, the
7787         first Thursday of a year is in week 1 of that year.
7788        </para>
7789        <para>
7790         In the ISO week-numbering system, it is possible for early-January
7791         dates to be part of the 52nd or 53rd week of the previous year, and for
7792         late-December dates to be part of the first week of the next year.
7793         For example, <literal>2005-01-01</> is part of the 53rd week of year
7794         2004, and <literal>2006-01-01</> is part of the 52nd week of year
7795         2005, while <literal>2012-12-31</> is part of the first week of 2013.
7796         It's recommended to use the <literal>isoyear</> field together with
7797         <literal>week</> to get consistent results.
7798        </para>
7799
7800 <screen>
7801 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
7802 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
7803 </screen>
7804       </listitem>
7805      </varlistentry>
7806
7807      <varlistentry>
7808       <term><literal>year</literal></term>
7809       <listitem>
7810        <para>
7811         The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting
7812         <literal>BC</> years from <literal>AD</> years should be done with care.
7813        </para>
7814
7815 <screen>
7816 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
7817 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
7818 </screen>
7819       </listitem>
7820      </varlistentry>
7821
7822     </variablelist>
7823    </para>
7824
7825    <note>
7826     <para>
7827      When the input value is +/-Infinity, <function>extract</> returns
7828      +/-Infinity for monotonically-increasing fields (<literal>epoch</>,
7829      <literal>julian</>, <literal>year</>, <literal>isoyear</>,
7830      <literal>decade</>, <literal>century</>, and <literal>millennium</>).
7831      For other fields, NULL is returned.  <productname>PostgreSQL</>
7832      versions before 9.6 returned zero for all cases of infinite input.
7833     </para>
7834    </note>
7835
7836    <para>
7837     The <function>extract</function> function is primarily intended
7838     for computational processing.  For formatting date/time values for
7839     display, see <xref linkend="functions-formatting">.
7840    </para>
7841
7842    <para>
7843     The <function>date_part</function> function is modeled on the traditional
7844     <productname>Ingres</productname> equivalent to the
7845     <acronym>SQL</acronym>-standard function <function>extract</function>:
7846 <synopsis>
7847 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
7848 </synopsis>
7849     Note that here the <replaceable>field</replaceable> parameter needs to
7850     be a string value, not a name.  The valid field names for
7851     <function>date_part</function> are the same as for
7852     <function>extract</function>.
7853    </para>
7854
7855 <screen>
7856 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
7857 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
7858
7859 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
7860 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
7861 </screen>
7862
7863   </sect2>
7864
7865   <sect2 id="functions-datetime-trunc">
7866    <title><function>date_trunc</function></title>
7867
7868    <indexterm>
7869     <primary>date_trunc</primary>
7870    </indexterm>
7871
7872    <para>
7873     The function <function>date_trunc</function> is conceptually
7874     similar to the <function>trunc</function> function for numbers.
7875    </para>
7876
7877    <para>
7878 <synopsis>
7879 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
7880 </synopsis>
7881     <replaceable>source</replaceable> is a value expression of type
7882     <type>timestamp</type> or <type>interval</>.
7883     (Values of type <type>date</type> and
7884     <type>time</type> are cast automatically to <type>timestamp</type> or
7885     <type>interval</>, respectively.)
7886     <replaceable>field</replaceable> selects to which precision to
7887     truncate the input value.  The return value is of type
7888     <type>timestamp</type> or <type>interval</>
7889     with all fields that are less significant than the
7890     selected one set to zero (or one, for day and month).
7891    </para>
7892
7893    <para>
7894     Valid values for <replaceable>field</replaceable> are:
7895     <simplelist>
7896      <member><literal>microseconds</literal></member>
7897      <member><literal>milliseconds</literal></member>
7898      <member><literal>second</literal></member>
7899      <member><literal>minute</literal></member>
7900      <member><literal>hour</literal></member>
7901      <member><literal>day</literal></member>
7902      <member><literal>week</literal></member>
7903      <member><literal>month</literal></member>
7904      <member><literal>quarter</literal></member>
7905      <member><literal>year</literal></member>
7906      <member><literal>decade</literal></member>
7907      <member><literal>century</literal></member>
7908      <member><literal>millennium</literal></member>
7909     </simplelist>
7910    </para>
7911
7912    <para>
7913     Examples:
7914 <screen>
7915 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
7916 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
7917
7918 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
7919 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
7920 </screen>
7921    </para>
7922   </sect2>
7923
7924   <sect2 id="functions-datetime-zoneconvert">
7925    <title><literal>AT TIME ZONE</literal></title>
7926
7927    <indexterm>
7928     <primary>time zone</primary>
7929     <secondary>conversion</secondary>
7930    </indexterm>
7931
7932    <indexterm>
7933     <primary>AT TIME ZONE</primary>
7934    </indexterm>
7935
7936    <para>
7937     The <literal>AT TIME ZONE</literal> construct allows conversions
7938     of time stamps to different time zones.  <xref
7939     linkend="functions-datetime-zoneconvert-table"> shows its
7940     variants.
7941    </para>
7942
7943     <table id="functions-datetime-zoneconvert-table">
7944      <title><literal>AT TIME ZONE</literal> Variants</title>
7945      <tgroup cols="3">
7946       <thead>
7947        <row>
7948         <entry>Expression</entry>
7949         <entry>Return Type</entry>
7950         <entry>Description</entry>
7951        </row>
7952       </thead>
7953
7954       <tbody>
7955        <row>
7956         <entry>
7957          <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7958         </entry>
7959         <entry><type>timestamp with time zone</type></entry>
7960         <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
7961        </row>
7962
7963        <row>
7964         <entry>
7965          <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7966         </entry>
7967         <entry><type>timestamp without time zone</type></entry>
7968         <entry>Convert given time stamp <emphasis>with time zone</> to the new time
7969         zone, with no time zone designation</entry>
7970        </row>
7971
7972        <row>
7973         <entry>
7974          <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
7975         </entry>
7976         <entry><type>time with time zone</type></entry>
7977         <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
7978        </row>
7979       </tbody>
7980      </tgroup>
7981     </table>
7982
7983    <para>
7984     In these expressions, the desired time zone <replaceable>zone</> can be
7985     specified either as a text string (e.g., <literal>'PST'</literal>)
7986     or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
7987     In the text case, a time zone name can be specified in any of the ways
7988     described in <xref linkend="datatype-timezones">.
7989    </para>
7990
7991    <para>
7992     Examples (assuming the local time zone is <literal>PST8PDT</>):
7993 <screen>
7994 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
7995 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
7996
7997 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
7998 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
7999 </screen>
8000     The first example takes a time stamp without time zone and interprets it as MST time
8001     (UTC-7), which is then converted to PST (UTC-8) for display.  The second example takes
8002     a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
8003    </para>
8004
8005    <para>
8006     The function <literal><function>timezone</function>(<replaceable>zone</>,
8007     <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
8008     <literal><replaceable>timestamp</> AT TIME ZONE
8009     <replaceable>zone</></literal>.
8010    </para>
8011   </sect2>
8012
8013   <sect2 id="functions-datetime-current">
8014    <title>Current Date/Time</title>
8015
8016    <indexterm>
8017     <primary>date</primary>
8018     <secondary>current</secondary>
8019    </indexterm>
8020
8021    <indexterm>
8022     <primary>time</primary>
8023     <secondary>current</secondary>
8024    </indexterm>
8025
8026    <para>
8027     <productname>PostgreSQL</productname> provides a number of functions
8028     that return values related to the current date and time.  These
8029     SQL-standard functions all return values based on the start time of
8030     the current transaction:
8031 <synopsis>
8032 CURRENT_DATE
8033 CURRENT_TIME
8034 CURRENT_TIMESTAMP
8035 CURRENT_TIME(<replaceable>precision</replaceable>)
8036 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
8037 LOCALTIME
8038 LOCALTIMESTAMP
8039 LOCALTIME(<replaceable>precision</replaceable>)
8040 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
8041 </synopsis>
8042     </para>
8043
8044     <para>
8045      <function>CURRENT_TIME</function> and
8046      <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
8047      <function>LOCALTIME</function> and
8048      <function>LOCALTIMESTAMP</function> deliver values without time zone.
8049     </para>
8050
8051     <para>
8052      <function>CURRENT_TIME</function>,
8053      <function>CURRENT_TIMESTAMP</function>,
8054      <function>LOCALTIME</function>, and
8055      <function>LOCALTIMESTAMP</function>
8056      can optionally take
8057      a precision parameter, which causes the result to be rounded
8058      to that many fractional digits in the seconds field.  Without a precision parameter,
8059      the result is given to the full available precision.
8060     </para>
8061
8062    <para>
8063     Some examples:
8064 <screen>
8065 SELECT CURRENT_TIME;
8066 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
8067
8068 SELECT CURRENT_DATE;
8069 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
8070
8071 SELECT CURRENT_TIMESTAMP;
8072 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
8073
8074 SELECT CURRENT_TIMESTAMP(2);
8075 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
8076
8077 SELECT LOCALTIMESTAMP;
8078 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
8079 </screen>
8080    </para>
8081
8082    <para>
8083     Since these functions return
8084     the start time of the current transaction, their values do not
8085     change during the transaction. This is considered a feature:
8086     the intent is to allow a single transaction to have a consistent
8087     notion of the <quote>current</quote> time, so that multiple
8088     modifications within the same transaction bear the same
8089     time stamp.
8090    </para>
8091
8092    <note>
8093     <para>
8094      Other database systems might advance these values more
8095      frequently.
8096     </para>
8097    </note>
8098
8099    <para>
8100     <productname>PostgreSQL</productname> also provides functions that
8101     return the start time of the current statement, as well as the actual
8102     current time at the instant the function is called.  The complete list
8103     of non-SQL-standard time functions is:
8104 <synopsis>
8105 transaction_timestamp()
8106 statement_timestamp()
8107 clock_timestamp()
8108 timeofday()
8109 now()
8110 </synopsis>
8111    </para>
8112
8113    <para>
8114     <function>transaction_timestamp()</> is equivalent to
8115     <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
8116     what it returns.
8117     <function>statement_timestamp()</> returns the start time of the current
8118     statement (more specifically, the time of receipt of the latest command
8119     message from the client).
8120     <function>statement_timestamp()</> and <function>transaction_timestamp()</>
8121     return the same value during the first command of a transaction, but might
8122     differ during subsequent commands.
8123     <function>clock_timestamp()</> returns the actual current time, and
8124     therefore its value changes even within a single SQL command.
8125     <function>timeofday()</> is a historical
8126     <productname>PostgreSQL</productname> function.  Like
8127     <function>clock_timestamp()</>, it returns the actual current time,
8128     but as a formatted <type>text</> string rather than a <type>timestamp
8129     with time zone</> value.
8130     <function>now()</> is a traditional <productname>PostgreSQL</productname>
8131     equivalent to <function>transaction_timestamp()</function>.
8132    </para>
8133
8134    <para>
8135     All the date/time data types also accept the special literal value
8136     <literal>now</literal> to specify the current date and time (again,
8137     interpreted as the transaction start time).  Thus,
8138     the following three all return the same result:
8139 <programlisting>
8140 SELECT CURRENT_TIMESTAMP;
8141 SELECT now();
8142 SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
8143 </programlisting>
8144    </para>
8145
8146     <tip>
8147      <para>
8148       You do not want to use the third form when specifying a <literal>DEFAULT</>
8149       clause while creating a table.  The system will convert <literal>now</literal>
8150       to a <type>timestamp</type> as soon as the constant is parsed, so that when
8151       the default value is needed,
8152       the time of the table creation would be used!  The first two
8153       forms will not be evaluated until the default value is used,
8154       because they are function calls.  Thus they will give the desired
8155       behavior of defaulting to the time of row insertion.
8156      </para>
8157     </tip>
8158   </sect2>
8159
8160   <sect2 id="functions-datetime-delay">
8161    <title>Delaying Execution</title>
8162
8163    <indexterm>
8164     <primary>pg_sleep</primary>
8165    </indexterm>
8166    <indexterm>
8167     <primary>pg_sleep_for</primary>
8168    </indexterm>
8169    <indexterm>
8170     <primary>pg_sleep_until</primary>
8171    </indexterm>
8172    <indexterm>
8173     <primary>sleep</primary>
8174    </indexterm>
8175    <indexterm>
8176     <primary>delay</primary>
8177    </indexterm>
8178
8179    <para>
8180     The following functions are available to delay execution of the server
8181     process:
8182 <synopsis>
8183 pg_sleep(<replaceable>seconds</replaceable>)
8184 pg_sleep_for(<type>interval</>)
8185 pg_sleep_until(<type>timestamp with time zone</>)
8186 </synopsis>
8187
8188     <function>pg_sleep</function> makes the current session's process
8189     sleep until <replaceable>seconds</replaceable> seconds have
8190     elapsed.  <replaceable>seconds</replaceable> is a value of type
8191     <type>double precision</>, so fractional-second delays can be specified.
8192     <function>pg_sleep_for</function> is a convenience function for larger
8193     sleep times specified as an <type>interval</>.
8194     <function>pg_sleep_until</function> is a convenience function for when
8195     a specific wake-up time is desired.
8196     For example:
8197
8198 <programlisting>
8199 SELECT pg_sleep(1.5);
8200 SELECT pg_sleep_for('5 minutes');
8201 SELECT pg_sleep_until('tomorrow 03:00');
8202 </programlisting>
8203    </para>
8204
8205    <note>
8206      <para>
8207       The effective resolution of the sleep interval is platform-specific;
8208       0.01 seconds is a common value.  The sleep delay will be at least as long
8209       as specified. It might be longer depending on factors such as server load.
8210       In particular, <function>pg_sleep_until</function> is not guaranteed to
8211       wake up exactly at the specified time, but it will not wake up any earlier.
8212      </para>
8213    </note>
8214
8215    <warning>
8216      <para>
8217       Make sure that your session does not hold more locks than necessary
8218       when calling <function>pg_sleep</function> or its variants.  Otherwise
8219       other sessions might have to wait for your sleeping process, slowing down
8220       the entire system.
8221      </para>
8222    </warning>
8223   </sect2>
8224
8225  </sect1>
8226
8227
8228  <sect1 id="functions-enum">
8229   <title>Enum Support Functions</title>
8230
8231   <para>
8232    For enum types (described in <xref linkend="datatype-enum">),
8233    there are several functions that allow cleaner programming without
8234    hard-coding particular values of an enum type.
8235    These are listed in <xref linkend="functions-enum-table">. The examples
8236    assume an enum type created as:
8237
8238 <programlisting>
8239 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
8240 </programlisting>
8241
8242   </para>
8243
8244   <table id="functions-enum-table">
8245     <title>Enum Support Functions</title>
8246     <tgroup cols="4">
8247      <thead>
8248       <row>
8249        <entry>Function</entry>
8250        <entry>Description</entry>
8251        <entry>Example</entry>
8252        <entry>Example Result</entry>
8253       </row>
8254      </thead>
8255      <tbody>
8256       <row>
8257        <entry>
8258          <indexterm>
8259           <primary>enum_first</primary>
8260          </indexterm>
8261          <literal>enum_first(anyenum)</literal>
8262        </entry>
8263        <entry>Returns the first value of the input enum type</entry>
8264        <entry><literal>enum_first(null::rainbow)</literal></entry>
8265        <entry><literal>red</literal></entry>
8266       </row>
8267       <row>
8268        <entry>
8269          <indexterm>
8270           <primary>enum_last</primary>
8271          </indexterm>
8272          <literal>enum_last(anyenum)</literal>
8273        </entry>
8274        <entry>Returns the last value of the input enum type</entry>
8275        <entry><literal>enum_last(null::rainbow)</literal></entry>
8276        <entry><literal>purple</literal></entry>
8277       </row>
8278       <row>
8279        <entry>
8280          <indexterm>
8281           <primary>enum_range</primary>
8282          </indexterm>
8283          <literal>enum_range(anyenum)</literal>
8284        </entry>
8285        <entry>Returns all values of the input enum type in an ordered array</entry>
8286        <entry><literal>enum_range(null::rainbow)</literal></entry>
8287        <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
8288       </row>
8289       <row>
8290        <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
8291        <entry morerows="2">
8292         Returns the range between the two given enum values, as an ordered
8293         array. The values must be from the same enum type. If the first
8294         parameter is null, the result will start with the first value of
8295         the enum type.
8296         If the second parameter is null, the result will end with the last
8297         value of the enum type.
8298        </entry>
8299        <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
8300        <entry><literal>{orange,yellow,green}</literal></entry>
8301       </row>
8302       <row>
8303        <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
8304        <entry><literal>{red,orange,yellow,green}</literal></entry>
8305       </row>
8306       <row>
8307        <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
8308        <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
8309       </row>
8310      </tbody>
8311     </tgroup>
8312    </table>
8313
8314    <para>
8315     Notice that except for the two-argument form of <function>enum_range</>,
8316     these functions disregard the specific value passed to them; they care
8317     only about its declared data type.  Either null or a specific value of
8318     the type can be passed, with the same result.  It is more common to
8319     apply these functions to a table column or function argument than to
8320     a hardwired type name as suggested by the examples.
8321    </para>
8322  </sect1>
8323
8324  <sect1 id="functions-geometry">
8325   <title>Geometric Functions and Operators</title>
8326
8327    <para>
8328     The geometric types <type>point</type>, <type>box</type>,
8329     <type>lseg</type>, <type>line</type>, <type>path</type>,
8330     <type>polygon</type>, and <type>circle</type> have a large set of
8331     native support functions and operators, shown in <xref
8332     linkend="functions-geometry-op-table">, <xref
8333     linkend="functions-geometry-func-table">, and <xref
8334     linkend="functions-geometry-conv-table">.
8335    </para>
8336
8337    <caution>
8338     <para>
8339      Note that the <quote>same as</> operator, <literal>~=</>, represents
8340      the usual notion of equality for the <type>point</type>,
8341      <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
8342      Some of these types also have an <literal>=</> operator, but
8343      <literal>=</> compares
8344      for equal <emphasis>areas</> only.  The other scalar comparison operators
8345      (<literal>&lt;=</> and so on) likewise compare areas for these types.
8346     </para>
8347    </caution>
8348
8349    <table id="functions-geometry-op-table">
8350      <title>Geometric Operators</title>
8351      <tgroup cols="3">
8352       <thead>
8353        <row>
8354         <entry>Operator</entry>
8355         <entry>Description</entry>
8356         <entry>Example</entry>
8357        </row>
8358       </thead>
8359       <tbody>
8360        <row>
8361         <entry> <literal>+</literal> </entry>
8362         <entry>Translation</entry>
8363         <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
8364        </row>
8365        <row>
8366         <entry> <literal>-</literal> </entry>
8367         <entry>Translation</entry>
8368         <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
8369        </row>
8370        <row>
8371         <entry> <literal>*</literal> </entry>
8372         <entry>Scaling/rotation</entry>
8373         <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
8374        </row>
8375        <row>
8376         <entry> <literal>/</literal> </entry>
8377         <entry>Scaling/rotation</entry>
8378         <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
8379        </row>
8380        <row>
8381         <entry> <literal>#</literal> </entry>
8382         <entry>Point or box of intersection</entry>
8383         <entry><literal>box '((1,-1),(-1,1))' # box '((1,1),(-2,-2))'</literal></entry>
8384        </row>
8385        <row>
8386         <entry> <literal>#</literal> </entry>
8387         <entry>Number of points in path or polygon</entry>
8388         <entry><literal># path '((1,0),(0,1),(-1,0))'</literal></entry>
8389        </row>
8390        <row>
8391         <entry> <literal>@-@</literal> </entry>
8392         <entry>Length or circumference</entry>
8393         <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
8394        </row>
8395        <row>
8396         <entry> <literal>@@</literal> </entry>
8397         <entry>Center</entry>
8398         <entry><literal>@@ circle '((0,0),10)'</literal></entry>
8399        </row>
8400        <row>
8401         <entry> <literal>##</literal> </entry>
8402         <entry>Closest point to first operand on second operand</entry>
8403         <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
8404        </row>
8405        <row>
8406         <entry> <literal>&lt;-&gt;</literal> </entry>
8407         <entry>Distance between</entry>
8408         <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
8409        </row>
8410        <row>
8411         <entry> <literal>&amp;&amp;</literal> </entry>
8412         <entry>Overlaps?  (One point in common makes this true.)</entry>
8413         <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
8414        </row>
8415        <row>
8416         <entry> <literal>&lt;&lt;</literal> </entry>
8417         <entry>Is strictly left of?</entry>
8418         <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
8419        </row>
8420        <row>
8421         <entry> <literal>&gt;&gt;</literal> </entry>
8422         <entry>Is strictly right of?</entry>
8423         <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
8424        </row>
8425        <row>
8426         <entry> <literal>&amp;&lt;</literal> </entry>
8427         <entry>Does not extend to the right of?</entry>
8428         <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
8429        </row>
8430        <row>
8431         <entry> <literal>&amp;&gt;</literal> </entry>
8432         <entry>Does not extend to the left of?</entry>
8433         <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
8434        </row>
8435        <row>
8436         <entry> <literal>&lt;&lt;|</literal> </entry>
8437         <entry>Is strictly below?</entry>
8438         <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
8439        </row>
8440        <row>
8441         <entry> <literal>|&gt;&gt;</literal> </entry>
8442         <entry>Is strictly above?</entry>
8443         <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
8444        </row>
8445        <row>
8446         <entry> <literal>&amp;&lt;|</literal> </entry>
8447         <entry>Does not extend above?</entry>
8448         <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
8449        </row>
8450        <row>
8451         <entry> <literal>|&amp;&gt;</literal> </entry>
8452         <entry>Does not extend below?</entry>
8453         <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
8454        </row>
8455        <row>
8456         <entry> <literal>&lt;^</literal> </entry>
8457         <entry>Is below (allows touching)?</entry>
8458         <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
8459        </row>
8460        <row>
8461         <entry> <literal>&gt;^</literal> </entry>
8462         <entry>Is above (allows touching)?</entry>
8463         <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
8464        </row>
8465        <row>
8466         <entry> <literal>?#</literal> </entry>
8467         <entry>Intersects?</entry>
8468         <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
8469        </row>
8470        <row>
8471         <entry> <literal>?-</literal> </entry>
8472         <entry>Is horizontal?</entry>
8473         <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
8474        </row>
8475        <row>
8476         <entry> <literal>?-</literal> </entry>
8477         <entry>Are horizontally aligned?</entry>
8478         <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
8479        </row>
8480        <row>
8481         <entry> <literal>?|</literal> </entry>
8482         <entry>Is vertical?</entry>
8483         <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
8484        </row>
8485        <row>
8486         <entry> <literal>?|</literal> </entry>
8487         <entry>Are vertically aligned?</entry>
8488         <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
8489        </row>
8490        <row>
8491         <entry> <literal>?-|</literal> </entry>
8492         <entry>Is perpendicular?</entry>
8493         <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
8494        </row>
8495        <row>
8496         <entry> <literal>?||</literal> </entry>
8497         <entry>Are parallel?</entry>
8498         <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
8499        </row>
8500        <row>
8501         <entry> <literal>@&gt;</literal> </entry>
8502         <entry>Contains?</entry>
8503         <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
8504        </row>
8505        <row>
8506         <entry> <literal>&lt;@</literal> </entry>
8507         <entry>Contained in or on?</entry>
8508         <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
8509        </row>
8510        <row>
8511         <entry> <literal>~=</literal> </entry>
8512         <entry>Same as?</entry>
8513         <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
8514        </row>
8515       </tbody>
8516      </tgroup>
8517    </table>
8518
8519    <note>
8520     <para>
8521      Before <productname>PostgreSQL</productname> 8.2, the containment
8522      operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
8523      called <literal>~</> and <literal>@</>.  These names are still
8524      available, but are deprecated and will eventually be removed.
8525     </para>
8526    </note>
8527
8528    <indexterm>
8529     <primary>area</primary>
8530    </indexterm>
8531    <indexterm>
8532     <primary>center</primary>
8533    </indexterm>
8534    <indexterm>
8535     <primary>diameter</primary>
8536    </indexterm>
8537    <indexterm>
8538     <primary>height</primary>
8539    </indexterm>
8540    <indexterm>
8541     <primary>isclosed</primary>
8542    </indexterm>
8543    <indexterm>
8544     <primary>isopen</primary>
8545    </indexterm>
8546    <indexterm>
8547     <primary>length</primary>
8548    </indexterm>
8549    <indexterm>
8550     <primary>npoints</primary>
8551    </indexterm>
8552    <indexterm>
8553     <primary>pclose</primary>
8554    </indexterm>
8555    <indexterm>
8556     <primary>popen</primary>
8557    </indexterm>
8558    <indexterm>
8559     <primary>radius</primary>
8560    </indexterm>
8561    <indexterm>
8562     <primary>width</primary>
8563    </indexterm>
8564
8565    <table id="functions-geometry-func-table">
8566      <title>Geometric Functions</title>
8567      <tgroup cols="4">
8568       <thead>
8569        <row>
8570         <entry>Function</entry>
8571         <entry>Return Type</entry>
8572         <entry>Description</entry>
8573         <entry>Example</entry>
8574        </row>
8575       </thead>
8576       <tbody>
8577        <row>
8578         <entry><literal><function>area(<replaceable>object</>)</function></literal></entry>
8579         <entry><type>double precision</type></entry>
8580         <entry>area</entry>
8581         <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
8582        </row>
8583        <row>
8584         <entry><literal><function>center(<replaceable>object</>)</function></literal></entry>
8585         <entry><type>point</type></entry>
8586         <entry>center</entry>
8587         <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
8588        </row>
8589        <row>
8590         <entry><literal><function>diameter(<type>circle</>)</function></literal></entry>
8591         <entry><type>double precision</type></entry>
8592         <entry>diameter of circle</entry>
8593         <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
8594        </row>
8595        <row>
8596         <entry><literal><function>height(<type>box</>)</function></literal></entry>
8597         <entry><type>double precision</type></entry>
8598         <entry>vertical size of box</entry>
8599         <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
8600        </row>
8601        <row>
8602         <entry><literal><function>isclosed(<type>path</>)</function></literal></entry>
8603         <entry><type>boolean</type></entry>
8604         <entry>a closed path?</entry>
8605         <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
8606        </row>
8607        <row>
8608         <entry><literal><function>isopen(<type>path</>)</function></literal></entry>
8609         <entry><type>boolean</type></entry>
8610         <entry>an open path?</entry>
8611         <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
8612        </row>
8613        <row>
8614         <entry><literal><function>length(<replaceable>object</>)</function></literal></entry>
8615         <entry><type>double precision</type></entry>
8616         <entry>length</entry>
8617         <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
8618        </row>
8619        <row>
8620         <entry><literal><function>npoints(<type>path</>)</function></literal></entry>
8621         <entry><type>int</type></entry>
8622         <entry>number of points</entry>
8623         <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
8624        </row>
8625        <row>
8626         <entry><literal><function>npoints(<type>polygon</>)</function></literal></entry>
8627         <entry><type>int</type></entry>
8628         <entry>number of points</entry>
8629         <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
8630        </row>
8631        <row>
8632         <entry><literal><function>pclose(<type>path</>)</function></literal></entry>
8633         <entry><type>path</type></entry>
8634         <entry>convert path to closed</entry>
8635         <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
8636        </row>
8637 <![IGNORE[
8638 <!-- Not defined by this name. Implements the intersection operator '#' -->
8639        <row>
8640         <entry><literal><function>point(<type>lseg</>, <type>lseg</>)</function></literal></entry>
8641         <entry><type>point</type></entry>
8642         <entry>intersection</entry>
8643         <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
8644        </row>
8645 ]]>
8646        <row>
8647         <entry><literal><function>popen(<type>path</>)</function></literal></entry>
8648         <entry><type>path</type></entry>
8649         <entry>convert path to open</entry>
8650         <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
8651        </row>
8652        <row>
8653         <entry><literal><function>radius(<type>circle</type>)</function></literal></entry>
8654         <entry><type>double precision</type></entry>
8655         <entry>radius of circle</entry>
8656         <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
8657        </row>
8658        <row>
8659         <entry><literal><function>width(<type>box</>)</function></literal></entry>
8660         <entry><type>double precision</type></entry>
8661         <entry>horizontal size of box</entry>
8662         <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
8663        </row>
8664       </tbody>
8665      </tgroup>
8666    </table>
8667
8668    <table id="functions-geometry-conv-table">
8669      <title>Geometric Type Conversion Functions</title>
8670      <tgroup cols="4">
8671       <thead>
8672        <row>
8673         <entry>Function</entry>
8674         <entry>Return Type</entry>
8675         <entry>Description</entry>
8676         <entry>Example</entry>
8677        </row>
8678       </thead>
8679       <tbody>
8680        <row>
8681         <entry>
8682          <indexterm>
8683           <primary>box</primary>
8684          </indexterm>
8685          <literal><function>box(<type>circle</type>)</function></literal>
8686         </entry>
8687         <entry><type>box</type></entry>
8688         <entry>circle to box</entry>
8689         <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
8690        </row>
8691        <row>
8692         <entry><literal><function>box(<type>point</type>)</function></literal></entry>
8693         <entry><type>box</type></entry>
8694         <entry>point to empty box</entry>
8695         <entry><literal>box(point '(0,0)')</literal></entry>
8696        </row>
8697        <row>
8698         <entry><literal><function>box(<type>point</type>, <type>point</type>)</function></literal></entry>
8699         <entry><type>box</type></entry>
8700         <entry>points to box</entry>
8701         <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
8702        </row>
8703        <row>
8704         <entry><literal><function>box(<type>polygon</type>)</function></literal></entry>
8705         <entry><type>box</type></entry>
8706         <entry>polygon to box</entry>
8707         <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8708        </row>
8709        <row>
8710         <entry><literal><function>bound_box(<type>box</type>, <type>box</type>)</function></literal></entry>
8711         <entry><type>box</type></entry>
8712         <entry>boxes to bounding box</entry>
8713         <entry><literal>bound_box(box '((0,0),(1,1))', box '((3,3),(4,4))')</literal></entry>
8714        </row>
8715        <row>
8716         <entry>
8717          <indexterm>
8718           <primary>circle</primary>
8719          </indexterm>
8720          <literal><function>circle(<type>box</type>)</function></literal>
8721         </entry>
8722         <entry><type>circle</type></entry>
8723         <entry>box to circle</entry>
8724         <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
8725        </row>
8726        <row>
8727         <entry><literal><function>circle(<type>point</type>, <type>double precision</type>)</function></literal></entry>
8728         <entry><type>circle</type></entry>
8729         <entry>center and radius to circle</entry>
8730         <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
8731        </row>
8732        <row>
8733         <entry><literal><function>circle(<type>polygon</type>)</function></literal></entry>
8734         <entry><type>circle</type></entry>
8735         <entry>polygon to circle</entry>
8736         <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8737        </row>
8738        <row>
8739         <entry><literal><function>line(<type>point</type>, <type>point</type>)</function></literal></entry>
8740         <entry><type>line</type></entry>
8741         <entry>points to line</entry>
8742         <entry><literal>line(point '(-1,0)', point '(1,0)')</literal></entry>
8743        </row>
8744        <row>
8745         <entry>
8746          <indexterm>
8747           <primary>lseg</primary>
8748          </indexterm>
8749          <literal><function>lseg(<type>box</type>)</function></literal>
8750         </entry>
8751         <entry><type>lseg</type></entry>
8752         <entry>box diagonal to line segment</entry>
8753         <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
8754        </row>
8755        <row>
8756         <entry><literal><function>lseg(<type>point</type>, <type>point</type>)</function></literal></entry>
8757         <entry><type>lseg</type></entry>
8758         <entry>points to line segment</entry>
8759         <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
8760        </row>
8761        <row>
8762         <entry>
8763          <indexterm>
8764           <primary>path</primary>
8765          </indexterm>
8766          <literal><function>path(<type>polygon</type>)</function></literal>
8767         </entry>
8768         <entry><type>path</type></entry>
8769         <entry>polygon to path</entry>
8770         <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8771        </row>
8772        <row>
8773         <entry>
8774          <indexterm>
8775           <primary>point</primary>
8776          </indexterm>
8777          <literal><function>point</function>(<type>double
8778          precision</type>, <type>double precision</type>)</literal>
8779         </entry>
8780         <entry><type>point</type></entry>
8781         <entry>construct point</entry>
8782         <entry><literal>point(23.4, -44.5)</literal></entry>
8783        </row>
8784        <row>
8785         <entry><literal><function>point(<type>box</type>)</function></literal></entry>
8786         <entry><type>point</type></entry>
8787         <entry>center of box</entry>
8788         <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
8789        </row>
8790        <row>
8791         <entry><literal><function>point(<type>circle</type>)</function></literal></entry>
8792         <entry><type>point</type></entry>
8793         <entry>center of circle</entry>
8794         <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
8795        </row>
8796        <row>
8797         <entry><literal><function>point(<type>lseg</type>)</function></literal></entry>
8798         <entry><type>point</type></entry>
8799         <entry>center of line segment</entry>
8800         <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
8801        </row>
8802        <row>
8803         <entry><literal><function>point(<type>polygon</type>)</function></literal></entry>
8804         <entry><type>point</type></entry>
8805         <entry>center of polygon</entry>
8806         <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
8807        </row>
8808        <row>
8809         <entry>
8810          <indexterm>
8811           <primary>polygon</primary>
8812          </indexterm>
8813          <literal><function>polygon(<type>box</type>)</function></literal>
8814         </entry>
8815         <entry><type>polygon</type></entry>
8816         <entry>box to 4-point polygon</entry>
8817         <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
8818        </row>
8819        <row>
8820         <entry><literal><function>polygon(<type>circle</type>)</function></literal></entry>
8821         <entry><type>polygon</type></entry>
8822         <entry>circle to 12-point polygon</entry>
8823         <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
8824        </row>
8825        <row>
8826         <entry><literal><function>polygon(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</function></literal></entry>
8827         <entry><type>polygon</type></entry>
8828         <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
8829         <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
8830        </row>
8831        <row>
8832         <entry><literal><function>polygon(<type>path</type>)</function></literal></entry>
8833         <entry><type>polygon</type></entry>
8834         <entry>path to polygon</entry>
8835         <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
8836        </row>
8837       </tbody>
8838      </tgroup>
8839    </table>
8840
8841     <para>
8842      It is possible to access the two component numbers of a <type>point</>
8843      as though the point were an array with indexes 0 and 1.  For example, if
8844      <literal>t.p</> is a <type>point</> column then
8845      <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
8846      <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
8847      In the same way, a value of type <type>box</> or <type>lseg</> can be treated
8848      as an array of two <type>point</> values.
8849     </para>
8850
8851     <para>
8852      The <function>area</function> function works for the types
8853      <type>box</type>, <type>circle</type>, and <type>path</type>.
8854      The <function>area</function> function only works on the
8855      <type>path</type> data type if the points in the
8856      <type>path</type> are non-intersecting.  For example, the
8857      <type>path</type>
8858      <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
8859      will not work;  however, the following visually identical
8860      <type>path</type>
8861      <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
8862      will work.  If the concept of an intersecting versus
8863      non-intersecting <type>path</type> is confusing, draw both of the
8864      above <type>path</type>s side by side on a piece of graph paper.
8865     </para>
8866
8867   </sect1>
8868
8869
8870  <sect1 id="functions-net">
8871   <title>Network Address Functions and Operators</title>
8872
8873   <para>
8874    <xref linkend="cidr-inet-operators-table"> shows the operators
8875    available for the <type>cidr</type> and <type>inet</type> types.
8876    The operators <literal>&lt;&lt;</literal>,
8877    <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>,
8878    <literal>&gt;&gt;=</literal>, and <literal>&amp;&amp;</literal>
8879    test for subnet inclusion.  They
8880    consider only the network parts of the two addresses (ignoring any
8881    host part) and determine whether one network is identical to
8882    or a subnet of the other.
8883   </para>
8884
8885     <table id="cidr-inet-operators-table">
8886      <title><type>cidr</type> and <type>inet</type> Operators</title>
8887      <tgroup cols="3">
8888       <thead>
8889        <row>
8890         <entry>Operator</entry>
8891         <entry>Description</entry>
8892         <entry>Example</entry>
8893        </row>
8894       </thead>
8895       <tbody>
8896        <row>
8897         <entry> <literal>&lt;</literal> </entry>
8898         <entry>is less than</entry>
8899         <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
8900        </row>
8901        <row>
8902         <entry> <literal>&lt;=</literal> </entry>
8903         <entry>is less than or equal</entry>
8904         <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
8905        </row>
8906        <row>
8907         <entry> <literal>=</literal> </entry>
8908         <entry>equals</entry>
8909         <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
8910        </row>
8911        <row>
8912         <entry> <literal>&gt;=</literal> </entry>
8913         <entry>is greater or equal</entry>
8914         <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
8915        </row>
8916        <row>
8917         <entry> <literal>&gt;</literal> </entry>
8918         <entry>is greater than</entry>
8919         <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
8920        </row>
8921        <row>
8922         <entry> <literal>&lt;&gt;</literal> </entry>
8923         <entry>is not equal</entry>
8924         <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
8925        </row>
8926        <row>
8927         <entry> <literal>&lt;&lt;</literal> </entry>
8928         <entry>is contained by</entry>
8929         <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
8930        </row>
8931        <row>
8932         <entry> <literal>&lt;&lt;=</literal> </entry>
8933         <entry>is contained by or equals</entry>
8934         <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
8935        </row>
8936        <row>
8937         <entry> <literal>&gt;&gt;</literal> </entry>
8938         <entry>contains</entry>
8939         <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
8940        </row>
8941        <row>
8942         <entry> <literal>&gt;&gt;=</literal> </entry>
8943         <entry>contains or equals</entry>
8944         <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
8945        </row>
8946        <row>
8947         <entry> <literal>&amp;&amp;</literal> </entry>
8948         <entry>contains or is contained by</entry>
8949         <entry><literal>inet '192.168.1/24' &amp;&amp; inet '192.168.1.80/28'</literal></entry>
8950        </row>
8951        <row>
8952         <entry> <literal>~</literal> </entry>
8953         <entry>bitwise NOT</entry>
8954         <entry><literal>~ inet '192.168.1.6'</literal></entry>
8955        </row>
8956        <row>
8957         <entry> <literal>&amp;</literal> </entry>
8958         <entry>bitwise AND</entry>
8959         <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
8960        </row>
8961        <row>
8962         <entry> <literal>|</literal> </entry>
8963         <entry>bitwise OR</entry>
8964         <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
8965        </row>
8966        <row>
8967         <entry> <literal>+</literal> </entry>
8968         <entry>addition</entry>
8969         <entry><literal>inet '192.168.1.6' + 25</literal></entry>
8970        </row>
8971        <row>
8972         <entry> <literal>-</literal> </entry>
8973         <entry>subtraction</entry>
8974         <entry><literal>inet '192.168.1.43' - 36</literal></entry>
8975        </row>
8976        <row>
8977         <entry> <literal>-</literal> </entry>
8978         <entry>subtraction</entry>
8979         <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
8980        </row>
8981       </tbody>
8982      </tgroup>
8983     </table>
8984
8985   <para>
8986    <xref linkend="cidr-inet-functions-table"> shows the functions
8987    available for use with the <type>cidr</type> and <type>inet</type>
8988    types.  The <function>abbrev</function>, <function>host</function>,
8989    and <function>text</function>
8990    functions are primarily intended to offer alternative display
8991    formats.
8992   </para>
8993
8994     <table id="cidr-inet-functions-table">
8995      <title><type>cidr</type> and <type>inet</type> Functions</title>
8996      <tgroup cols="5">
8997       <thead>
8998        <row>
8999         <entry>Function</entry>
9000         <entry>Return Type</entry>
9001         <entry>Description</entry>
9002         <entry>Example</entry>
9003         <entry>Result</entry>
9004        </row>
9005       </thead>
9006       <tbody>
9007        <row>
9008         <entry>
9009          <indexterm>
9010           <primary>abbrev</primary>
9011          </indexterm>
9012          <literal><function>abbrev(<type>inet</type>)</function></literal>
9013         </entry>
9014         <entry><type>text</type></entry>
9015         <entry>abbreviated display format as text</entry>
9016         <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
9017         <entry><literal>10.1.0.0/16</literal></entry>
9018        </row>
9019        <row>
9020         <entry><literal><function>abbrev(<type>cidr</type>)</function></literal></entry>
9021         <entry><type>text</type></entry>
9022         <entry>abbreviated display format as text</entry>
9023         <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
9024         <entry><literal>10.1/16</literal></entry>
9025        </row>
9026        <row>
9027         <entry>
9028          <indexterm>
9029           <primary>broadcast</primary>
9030          </indexterm>
9031          <literal><function>broadcast(<type>inet</type>)</function></literal>
9032         </entry>
9033         <entry><type>inet</type></entry>
9034         <entry>broadcast address for network</entry>
9035         <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
9036         <entry><literal>192.168.1.255/24</literal></entry>
9037        </row>
9038        <row>
9039         <entry>
9040          <indexterm>
9041           <primary>family</primary>
9042          </indexterm>
9043          <literal><function>family(<type>inet</type>)</function></literal>
9044         </entry>
9045         <entry><type>int</type></entry>
9046         <entry>extract family of address; <literal>4</literal> for IPv4,
9047          <literal>6</literal> for IPv6</entry>
9048         <entry><literal>family('::1')</literal></entry>
9049         <entry><literal>6</literal></entry>
9050        </row>
9051        <row>
9052         <entry>
9053          <indexterm>
9054           <primary>host</primary>
9055          </indexterm>
9056          <literal><function>host(<type>inet</type>)</function></literal>
9057         </entry>
9058         <entry><type>text</type></entry>
9059         <entry>extract IP address as text</entry>
9060         <entry><literal>host('192.168.1.5/24')</literal></entry>
9061         <entry><literal>192.168.1.5</literal></entry>
9062        </row>
9063        <row>
9064         <entry>
9065          <indexterm>
9066           <primary>hostmask</primary>
9067          </indexterm>
9068          <literal><function>hostmask(<type>inet</type>)</function></literal>
9069         </entry>
9070         <entry><type>inet</type></entry>
9071         <entry>construct host mask for network</entry>
9072         <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
9073         <entry><literal>0.0.0.3</literal></entry>
9074        </row>
9075        <row>
9076         <entry>
9077          <indexterm>
9078           <primary>masklen</primary>
9079          </indexterm>
9080          <literal><function>masklen(<type>inet</type>)</function></literal>
9081         </entry>
9082         <entry><type>int</type></entry>
9083         <entry>extract netmask length</entry>
9084         <entry><literal>masklen('192.168.1.5/24')</literal></entry>
9085         <entry><literal>24</literal></entry>
9086        </row>
9087        <row>
9088         <entry>
9089          <indexterm>
9090           <primary>netmask</primary>
9091          </indexterm>
9092          <literal><function>netmask(<type>inet</type>)</function></literal>
9093         </entry>
9094         <entry><type>inet</type></entry>
9095         <entry>construct netmask for network</entry>
9096         <entry><literal>netmask('192.168.1.5/24')</literal></entry>
9097         <entry><literal>255.255.255.0</literal></entry>
9098        </row>
9099        <row>
9100         <entry>
9101          <indexterm>
9102           <primary>network</primary>
9103          </indexterm>
9104          <literal><function>network(<type>inet</type>)</function></literal>
9105         </entry>
9106         <entry><type>cidr</type></entry>
9107         <entry>extract network part of address</entry>
9108         <entry><literal>network('192.168.1.5/24')</literal></entry>
9109         <entry><literal>192.168.1.0/24</literal></entry>
9110        </row>
9111        <row>
9112         <entry>
9113          <indexterm>
9114           <primary>set_masklen</primary>
9115          </indexterm>
9116          <literal><function>set_masklen(<type>inet</type>, <type>int</type>)</function></literal>
9117         </entry>
9118         <entry><type>inet</type></entry>
9119         <entry>set netmask length for <type>inet</type> value</entry>
9120         <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
9121         <entry><literal>192.168.1.5/16</literal></entry>
9122        </row>
9123        <row>
9124         <entry><literal><function>set_masklen(<type>cidr</type>, <type>int</type>)</function></literal></entry>
9125         <entry><type>cidr</type></entry>
9126         <entry>set netmask length for <type>cidr</type> value</entry>
9127         <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
9128         <entry><literal>192.168.0.0/16</literal></entry>
9129        </row>
9130        <row>
9131         <entry>
9132          <indexterm>
9133           <primary>text</primary>
9134          </indexterm>
9135          <literal><function>text(<type>inet</type>)</function></literal>
9136         </entry>
9137         <entry><type>text</type></entry>
9138         <entry>extract IP address and netmask length as text</entry>
9139         <entry><literal>text(inet '192.168.1.5')</literal></entry>
9140         <entry><literal>192.168.1.5/32</literal></entry>
9141        </row>
9142        <row>
9143         <entry>
9144          <indexterm>
9145           <primary>inet_same_family</primary>
9146          </indexterm>
9147          <literal><function>inet_same_family(<type>inet</type>, <type>inet</type>)</function></literal>
9148         </entry>
9149         <entry><type>boolean</type></entry>
9150         <entry>are the addresses from the same family?</entry>
9151         <entry><literal>inet_same_family('192.168.1.5/24', '::1')</literal></entry>
9152         <entry><literal>false</literal></entry>
9153        </row>
9154        <row>
9155         <entry>
9156          <indexterm>
9157           <primary>inet_merge</primary>
9158          </indexterm>
9159          <literal><function>inet_merge(<type>inet</type>, <type>inet</type>)</function></literal>
9160         </entry>
9161         <entry><type>cidr</type></entry>
9162         <entry>the smallest network which includes both of the given networks</entry>
9163         <entry><literal>inet_merge('192.168.1.5/24', '192.168.2.5/24')</literal></entry>
9164         <entry><literal>192.168.0.0/22</literal></entry>
9165        </row>
9166       </tbody>
9167      </tgroup>
9168     </table>
9169
9170   <para>
9171    Any <type>cidr</> value can be cast to <type>inet</> implicitly
9172    or explicitly; therefore, the functions shown above as operating on
9173    <type>inet</> also work on <type>cidr</> values.  (Where there are
9174    separate functions for <type>inet</> and <type>cidr</>, it is because
9175    the behavior should be different for the two cases.)
9176    Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
9177    When this is done, any bits to the right of the netmask are silently zeroed
9178    to create a valid <type>cidr</> value.
9179    In addition,
9180    you can cast a text value to <type>inet</> or <type>cidr</>
9181    using normal casting syntax: for example,
9182    <literal>inet(<replaceable>expression</>)</literal> or
9183    <literal><replaceable>colname</>::cidr</literal>.
9184   </para>
9185
9186   <para>
9187    <xref linkend="macaddr-functions-table"> shows the functions
9188    available for use with the <type>macaddr</type> type.  The function
9189    <literal><function>trunc(<type>macaddr</type>)</function></literal> returns a MAC
9190    address with the last 3 bytes set to zero.  This can be used to
9191    associate the remaining prefix with a manufacturer.
9192   </para>
9193
9194     <table id="macaddr-functions-table">
9195      <title><type>macaddr</type> Functions</title>
9196      <tgroup cols="5">
9197       <thead>
9198        <row>
9199         <entry>Function</entry>
9200         <entry>Return Type</entry>
9201         <entry>Description</entry>
9202         <entry>Example</entry>
9203         <entry>Result</entry>
9204        </row>
9205       </thead>
9206       <tbody>
9207        <row>
9208         <entry>
9209          <indexterm>
9210           <primary>trunc</primary>
9211          </indexterm>
9212          <literal><function>trunc(<type>macaddr</type>)</function></literal>
9213         </entry>
9214         <entry><type>macaddr</type></entry>
9215         <entry>set last 3 bytes to zero</entry>
9216         <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
9217         <entry><literal>12:34:56:00:00:00</literal></entry>
9218        </row>
9219       </tbody>
9220      </tgroup>
9221     </table>
9222
9223    <para>
9224     The <type>macaddr</type> type also supports the standard relational
9225     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
9226     lexicographical ordering, and the bitwise arithmetic operators
9227     (<literal>~</literal>, <literal>&amp;</literal> and <literal>|</literal>)
9228     for NOT, AND and OR.
9229    </para>
9230
9231    <para>
9232    <xref linkend="macaddr8-functions-table"> shows the functions
9233    available for use with the <type>macaddr8</type> type.  The function
9234    <literal><function>trunc(<type>macaddr8</type>)</function></literal> returns a MAC
9235    address with the last 5 bytes set to zero.  This can be used to
9236    associate the remaining prefix with a manufacturer.
9237   </para>
9238
9239     <table id="macaddr8-functions-table">
9240      <title><type>macaddr8</type> Functions</title>
9241      <tgroup cols="5">
9242       <thead>
9243        <row>
9244         <entry>Function</entry>
9245         <entry>Return Type</entry>
9246         <entry>Description</entry>
9247         <entry>Example</entry>
9248         <entry>Result</entry>
9249        </row>
9250       </thead>
9251       <tbody>
9252        <row>
9253         <entry>
9254          <indexterm>
9255           <primary>trunc</primary>
9256          </indexterm>
9257          <literal><function>trunc(<type>macaddr8</type>)</function></literal>
9258         </entry>
9259         <entry><type>macaddr8</type></entry>
9260         <entry>set last 5 bytes to zero</entry>
9261         <entry><literal>trunc(macaddr8 '12:34:56:78:90:ab:cd:ef')</literal></entry>
9262         <entry><literal>12:34:56:00:00:00:00:00</literal></entry>
9263        </row>
9264        <row>
9265         <entry>
9266          <indexterm>
9267           <primary>macaddr8_set7bit</primary>
9268          </indexterm>
9269          <literal><function>macaddr8_set7bit(<type>macaddr8</type>)</function></literal>
9270         </entry>
9271         <entry><type>macaddr8</type></entry>
9272         <entry>set 7th bit to one, also known as modified EUI-64, for inclusion in an IPv6 address</entry>
9273         <entry><literal>macaddr8_set7bit(macaddr8 '00:34:56:ab:cd:ef')</literal></entry>
9274         <entry><literal>02:34:56:ff:fe:ab:cd:ef</literal></entry>
9275        </row>
9276       </tbody>
9277      </tgroup>
9278     </table>
9279
9280    <para>
9281     The <type>macaddr8</type> type also supports the standard relational
9282     operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
9283     ordering, and the bitwise arithmetic operators (<literal>~</literal>,
9284     <literal>&amp;</literal> and <literal>|</literal>) for NOT, AND and OR.
9285    </para>
9286
9287   </sect1>
9288
9289
9290  <sect1 id="functions-textsearch">
9291   <title>Text Search Functions and Operators</title>
9292
9293    <indexterm zone="datatype-textsearch">
9294     <primary>full text search</primary>
9295     <secondary>functions and operators</secondary>
9296    </indexterm>
9297
9298    <indexterm zone="datatype-textsearch">
9299     <primary>text search</primary>
9300     <secondary>functions and operators</secondary>
9301    </indexterm>
9302
9303   <para>
9304    <xref linkend="textsearch-operators-table">,
9305    <xref linkend="textsearch-functions-table"> and
9306    <xref linkend="textsearch-functions-debug-table">
9307    summarize the functions and operators that are provided
9308    for full text searching.  See <xref linkend="textsearch"> for a detailed
9309    explanation of <productname>PostgreSQL</productname>'s text search
9310    facility.
9311   </para>
9312
9313     <table id="textsearch-operators-table">
9314      <title>Text Search Operators</title>
9315      <tgroup cols="5">
9316       <thead>
9317        <row>
9318         <entry>Operator</entry>
9319         <entry>Return Type</entry>
9320         <entry>Description</entry>
9321         <entry>Example</entry>
9322         <entry>Result</entry>
9323        </row>
9324       </thead>
9325       <tbody>
9326        <row>
9327         <entry> <literal>@@</literal> </entry>
9328         <entry><type>boolean</></entry>
9329         <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
9330         <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal></entry>
9331         <entry><literal>t</literal></entry>
9332        </row>
9333        <row>
9334         <entry> <literal>@@@</literal> </entry>
9335         <entry><type>boolean</></entry>
9336         <entry>deprecated synonym for <literal>@@</></entry>
9337         <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal></entry>
9338         <entry><literal>t</literal></entry>
9339        </row>
9340        <row>
9341         <entry> <literal>||</literal> </entry>
9342         <entry><type>tsvector</></entry>
9343         <entry>concatenate <type>tsvector</>s</entry>
9344         <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
9345         <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
9346        </row>
9347        <row>
9348         <entry> <literal>&amp;&amp;</literal> </entry>
9349         <entry><type>tsquery</></entry>
9350         <entry>AND <type>tsquery</>s together</entry>
9351         <entry><literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal></entry>
9352         <entry><literal>( 'fat' | 'rat' ) &amp; 'cat'</literal></entry>
9353        </row>
9354        <row>
9355         <entry> <literal>||</literal> </entry>
9356         <entry><type>tsquery</></entry>
9357         <entry>OR <type>tsquery</>s together</entry>
9358         <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
9359         <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
9360        </row>
9361        <row>
9362         <entry> <literal>!!</literal> </entry>
9363         <entry><type>tsquery</></entry>
9364         <entry>negate a <type>tsquery</></entry>
9365         <entry><literal>!! 'cat'::tsquery</literal></entry>
9366         <entry><literal>!'cat'</literal></entry>
9367        </row>
9368        <row>
9369         <entry> <literal>&lt;-&gt;</literal> </entry>
9370         <entry><type>tsquery</></entry>
9371         <entry><type>tsquery</> followed by <type>tsquery</></entry>
9372         <entry><literal>to_tsquery('fat') &lt;-&gt; to_tsquery('rat')</literal></entry>
9373         <entry><literal>'fat' &lt;-&gt; 'rat'</literal></entry>
9374        </row>
9375        <row>
9376         <entry> <literal>@&gt;</literal> </entry>
9377         <entry><type>boolean</></entry>
9378         <entry><type>tsquery</> contains another ?</entry>
9379         <entry><literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal></entry>
9380         <entry><literal>f</literal></entry>
9381        </row>
9382        <row>
9383         <entry> <literal>&lt;@</literal> </entry>
9384         <entry><type>boolean</></entry>
9385         <entry><type>tsquery</> is contained in ?</entry>
9386         <entry><literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal></entry>
9387         <entry><literal>t</literal></entry>
9388        </row>
9389       </tbody>
9390      </tgroup>
9391     </table>
9392
9393     <note>
9394      <para>
9395       The <type>tsquery</> containment operators consider only the lexemes
9396       listed in the two queries, ignoring the combining operators.
9397      </para>
9398     </note>
9399
9400     <para>
9401      In addition to the operators shown in the table, the ordinary B-tree
9402      comparison operators (<literal>=</>, <literal>&lt;</>, etc) are defined
9403      for types <type>tsvector</> and <type>tsquery</>.  These are not very
9404      useful for text searching but allow, for example, unique indexes to be
9405      built on columns of these types.
9406     </para>
9407
9408     <table id="textsearch-functions-table">
9409      <title>Text Search Functions</title>
9410      <tgroup cols="5">
9411       <thead>
9412        <row>
9413         <entry>Function</entry>
9414         <entry>Return Type</entry>
9415         <entry>Description</entry>
9416         <entry>Example</entry>
9417         <entry>Result</entry>
9418        </row>
9419       </thead>
9420       <tbody>
9421        <row>
9422         <entry>
9423          <indexterm>
9424           <primary>array_to_tsvector</primary>
9425          </indexterm>
9426          <literal><function>array_to_tsvector(<type>text[]</>)</function></literal>
9427         </entry>
9428         <entry><type>tsvector</type></entry>
9429         <entry>convert array of lexemes to <type>tsvector</type></entry>
9430         <entry><literal>array_to_tsvector('{fat,cat,rat}'::text[])</literal></entry>
9431         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
9432        </row>
9433        <row>
9434         <entry>
9435          <indexterm>
9436           <primary>get_current_ts_config</primary>
9437          </indexterm>
9438          <literal><function>get_current_ts_config()</function></literal>
9439         </entry>
9440         <entry><type>regconfig</type></entry>
9441         <entry>get default text search configuration</entry>
9442         <entry><literal>get_current_ts_config()</literal></entry>
9443         <entry><literal>english</literal></entry>
9444        </row>
9445        <row>
9446         <entry>
9447          <indexterm>
9448           <primary>length</primary>
9449          </indexterm>
9450          <literal><function>length(<type>tsvector</>)</function></literal>
9451         </entry>
9452         <entry><type>integer</type></entry>
9453         <entry>number of lexemes in <type>tsvector</></entry>
9454         <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
9455         <entry><literal>3</literal></entry>
9456        </row>
9457        <row>
9458         <entry>
9459          <indexterm>
9460           <primary>numnode</primary>
9461          </indexterm>
9462          <literal><function>numnode(<type>tsquery</>)</function></literal>
9463         </entry>
9464         <entry><type>integer</type></entry>
9465         <entry>number of lexemes plus operators in <type>tsquery</></entry>
9466         <entry><literal> numnode('(fat &amp; rat) | cat'::tsquery)</literal></entry>
9467         <entry><literal>5</literal></entry>
9468        </row>
9469        <row>
9470         <entry>
9471          <indexterm>
9472           <primary>plainto_tsquery</primary>
9473          </indexterm>
9474          <literal><function>plainto_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
9475         </entry>
9476         <entry><type>tsquery</type></entry>
9477         <entry>produce <type>tsquery</> ignoring punctuation</entry>
9478         <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
9479         <entry><literal>'fat' &amp; 'rat'</literal></entry>
9480        </row>
9481        <row>
9482         <entry>
9483          <indexterm>
9484           <primary>phraseto_tsquery</primary>
9485          </indexterm>
9486          <literal><function>phraseto_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
9487         </entry>
9488         <entry><type>tsquery</type></entry>
9489         <entry>produce <type>tsquery</> that searches for a phrase,
9490          ignoring punctuation</entry>
9491         <entry><literal>phraseto_tsquery('english', 'The Fat Rats')</literal></entry>
9492         <entry><literal>'fat' &lt;-&gt; 'rat'</literal></entry>
9493        </row>
9494        <row>
9495         <entry>
9496          <indexterm>
9497           <primary>querytree</primary>
9498          </indexterm>
9499          <literal><function>querytree(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</function></literal>
9500         </entry>
9501         <entry><type>text</type></entry>
9502         <entry>get indexable part of a <type>tsquery</></entry>
9503         <entry><literal>querytree('foo &amp; ! bar'::tsquery)</literal></entry>
9504         <entry><literal>'foo'</literal></entry>
9505        </row>
9506        <row>
9507         <entry>
9508          <indexterm>
9509           <primary>setweight</primary>
9510          </indexterm>
9511          <literal><function>setweight(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER">weight</replaceable> <type>"char"</>)</function></literal>
9512         </entry>
9513         <entry><type>tsvector</type></entry>
9514         <entry>assign <replaceable class="PARAMETER">weight</replaceable> to each element of <replaceable class="PARAMETER">vector</replaceable></entry>
9515         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
9516         <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
9517        </row>
9518        <row>
9519         <entry>
9520          <indexterm>
9521           <primary>setweight</primary>
9522           <secondary>setweight for specific lexeme(s)</secondary>
9523          </indexterm>
9524          <literal><function>setweight(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER">weight</replaceable> <type>"char"</>, <replaceable class="PARAMETER">lexemes</replaceable> <type>text[]</>)</function></literal>
9525         </entry>
9526         <entry><type>tsvector</type></entry>
9527         <entry>assign <replaceable class="PARAMETER">weight</replaceable> to elements of <replaceable class="PARAMETER">vector</replaceable> that are listed in <replaceable class="PARAMETER">lexemes</replaceable></entry>
9528         <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A', '{cat,rat}')</literal></entry>
9529         <entry><literal>'cat':3A 'fat':2,4 'rat':5A</literal></entry>
9530        </row>
9531        <row>
9532         <entry>
9533          <indexterm>
9534           <primary>strip</primary>
9535          </indexterm>
9536          <literal><function>strip(<type>tsvector</>)</function></literal>
9537         </entry>
9538         <entry><type>tsvector</type></entry>
9539         <entry>remove positions and weights from <type>tsvector</></entry>
9540         <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
9541         <entry><literal>'cat' 'fat' 'rat'</literal></entry>
9542        </row>
9543        <row>
9544         <entry>
9545          <indexterm>
9546           <primary>to_tsquery</primary>
9547          </indexterm>
9548          <literal><function>to_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
9549         </entry>
9550         <entry><type>tsquery</type></entry>
9551         <entry>normalize words and convert to <type>tsquery</></entry>
9552         <entry><literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal></entry>
9553         <entry><literal>'fat' &amp; 'rat'</literal></entry>
9554        </row>
9555        <row>
9556         <entry>
9557          <indexterm>
9558           <primary>to_tsvector</primary>
9559          </indexterm>
9560          <literal><function>to_tsvector(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</function></literal>
9561         </entry>
9562         <entry><type>tsvector</type></entry>
9563         <entry>reduce document text to <type>tsvector</></entry>
9564         <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
9565         <entry><literal>'fat':2 'rat':3</literal></entry>
9566        </row>
9567        <row>
9568         <entry>
9569          <indexterm>
9570           <primary>ts_delete</primary>
9571          </indexterm>
9572          <literal><function>ts_delete(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER">lexeme</replaceable> <type>text</>)</function></literal>
9573         </entry>
9574         <entry><type>tsvector</type></entry>
9575         <entry>remove given <replaceable class="PARAMETER">lexeme</replaceable> from <replaceable class="PARAMETER">vector</replaceable></entry>
9576         <entry><literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, 'fat')</literal></entry>
9577         <entry><literal>'cat':3 'rat':5A</literal></entry>
9578        </row>
9579        <row>
9580         <entry>
9581          <!-- previous indexterm entry covers this too -->
9582          <literal><function>ts_delete(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER">lexemes</replaceable> <type>text[]</>)</function></literal>
9583         </entry>
9584         <entry><type>tsvector</type></entry>
9585         <entry>remove any occurrence of lexemes in <replaceable class="PARAMETER">lexemes</replaceable> from <replaceable class="PARAMETER">vector</replaceable></entry>
9586         <entry><literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, ARRAY['fat','rat'])</literal></entry>
9587         <entry><literal>'cat':3</literal></entry>
9588        </row>
9589        <row>
9590         <entry>
9591          <indexterm>
9592           <primary>ts_filter</primary>
9593          </indexterm>
9594          <literal><function>ts_filter(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER">weights</replaceable> <type>"char"[]</>)</function></literal>
9595         </entry>
9596         <entry><type>tsvector</type></entry>
9597         <entry>select only elements with given <replaceable class="PARAMETER">weights</replaceable> from <replaceable class="PARAMETER">vector</replaceable></entry>
9598         <entry><literal>ts_filter('fat:2,4 cat:3b rat:5A'::tsvector, '{a,b}')</literal></entry>
9599         <entry><literal>'cat':3B 'rat':5A</literal></entry>
9600        </row>
9601        <row>
9602         <entry>
9603          <indexterm>
9604           <primary>ts_headline</primary>
9605          </indexterm>
9606          <literal><function>ts_headline(<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>)</function></literal>
9607         </entry>
9608         <entry><type>text</type></entry>
9609         <entry>display a query match</entry>
9610         <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
9611         <entry><literal>x y &lt;b&gt;z&lt;/b&gt;</literal></entry>
9612        </row>
9613        <row>
9614         <entry>
9615          <indexterm>
9616           <primary>ts_rank</primary>
9617          </indexterm>
9618          <literal><function>ts_rank(<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>)</function></literal>
9619         </entry>
9620         <entry><type>float4</type></entry>
9621         <entry>rank document for query</entry>
9622         <entry><literal>ts_rank(textsearch, query)</literal></entry>
9623         <entry><literal>0.818</literal></entry>
9624        </row>
9625        <row>
9626         <entry>
9627          <indexterm>
9628           <primary>ts_rank_cd</primary>
9629          </indexterm>
9630          <literal><function>ts_rank_cd(<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>)</function></literal>
9631         </entry>
9632         <entry><type>float4</type></entry>
9633         <entry>rank document for query using cover density</entry>
9634         <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
9635         <entry><literal>2.01317</literal></entry>
9636        </row>
9637        <row>
9638         <entry>
9639          <indexterm>
9640           <primary>ts_rewrite</primary>
9641          </indexterm>
9642          <literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">target</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">substitute</replaceable> <type>tsquery</>)</function></literal>
9643         </entry>
9644         <entry><type>tsquery</type></entry>
9645         <entry>replace <replaceable>target</> with <replaceable>substitute</>
9646          within query</entry>
9647         <entry><literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
9648         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
9649        </row>
9650        <row>
9651         <entry><literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</function></literal></entry>
9652         <entry><type>tsquery</type></entry>
9653         <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
9654         <entry><literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
9655         <entry><literal>'b' &amp; ( 'foo' | 'bar' )</literal></entry>
9656        </row>
9657        <row>
9658         <entry>
9659          <indexterm>
9660           <primary>tsquery_phrase</primary>
9661          </indexterm>
9662          <literal><function>tsquery_phrase(<replaceable class="PARAMETER">query1</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">query2</replaceable> <type>tsquery</>)</function></literal>
9663         </entry>
9664         <entry><type>tsquery</type></entry>
9665         <entry>make query that searches for <replaceable>query1</> followed
9666          by <replaceable>query2</> (same as <literal>&lt;-&gt;</>
9667          operator)</entry>
9668         <entry><literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))</literal></entry>
9669         <entry><literal>'fat' &lt;-&gt; 'cat'</literal></entry>
9670        </row>
9671        <row>
9672         <entry>
9673          <literal><function>tsquery_phrase(<replaceable class="PARAMETER">query1</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">query2</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">distance</replaceable> <type>integer</>)</function></literal>
9674         </entry>
9675         <entry><type>tsquery</type></entry>
9676         <entry>make query that searches for <replaceable>query1</> followed by
9677          <replaceable>query2</> at distance <replaceable>distance</></entry>
9678         <entry><literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'), 10)</literal></entry>
9679         <entry><literal>'fat' &lt;10&gt; 'cat'</literal></entry>
9680        </row>
9681        <row>
9682         <entry>
9683          <indexterm>
9684           <primary>tsvector_to_array</primary>
9685          </indexterm>
9686          <literal><function>tsvector_to_array(<type>tsvector</>)</function></literal>
9687         </entry>
9688         <entry><type>text[]</type></entry>
9689         <entry>convert <type>tsvector</> to array of lexemes</entry>
9690         <entry><literal>tsvector_to_array('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
9691         <entry><literal>{cat,fat,rat}</literal></entry>
9692        </row>
9693        <row>
9694         <entry>
9695          <indexterm>
9696           <primary>tsvector_update_trigger</primary>
9697          </indexterm>
9698          <literal><function>tsvector_update_trigger()</function></literal>
9699         </entry>
9700         <entry><type>trigger</type></entry>
9701         <entry>trigger function for automatic <type>tsvector</> column update</entry>
9702         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
9703         <entry><literal></literal></entry>
9704        </row>
9705        <row>
9706         <entry>
9707          <indexterm>
9708           <primary>tsvector_update_trigger_column</primary>
9709          </indexterm>
9710          <literal><function>tsvector_update_trigger_column()</function></literal>
9711         </entry>
9712         <entry><type>trigger</type></entry>
9713         <entry>trigger function for automatic <type>tsvector</> column update</entry>
9714         <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
9715         <entry><literal></literal></entry>
9716        </row>
9717        <row>
9718         <entry>
9719          <indexterm>
9720           <primary>unnest</primary>
9721           <secondary>for tsvector</secondary>
9722          </indexterm>
9723          <literal><function>unnest(<type>tsvector</>, OUT <replaceable class="PARAMETER">lexeme</> <type>text</>, OUT <replaceable class="PARAMETER">positions</> <type>smallint[]</>, OUT <replaceable class="PARAMETER">weights</> <type>text</>)</function></literal>
9724         </entry>
9725         <entry><type>setof record</type></entry>
9726         <entry>expand a tsvector to a set of rows</entry>
9727         <entry><literal>unnest('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
9728         <entry><literal>(cat,{3},{D}) ...</literal></entry>
9729        </row>
9730       </tbody>
9731      </tgroup>
9732     </table>
9733
9734   <note>
9735    <para>
9736     All the text search functions that accept an optional <type>regconfig</>
9737     argument will use the configuration specified by
9738     <xref linkend="guc-default-text-search-config">
9739     when that argument is omitted.
9740    </para>
9741   </note>
9742
9743   <para>
9744    The functions in
9745    <xref linkend="textsearch-functions-debug-table">
9746    are listed separately because they are not usually used in everyday text
9747    searching operations.  They are helpful for development and debugging
9748    of new text search configurations.
9749   </para>
9750
9751     <table id="textsearch-functions-debug-table">
9752      <title>Text Search Debugging Functions</title>
9753      <tgroup cols="5">
9754       <thead>
9755        <row>
9756         <entry>Function</entry>
9757         <entry>Return Type</entry>
9758         <entry>Description</entry>
9759         <entry>Example</entry>
9760         <entry>Result</entry>
9761        </row>
9762       </thead>
9763       <tbody>
9764        <row>
9765         <entry>
9766          <indexterm>
9767           <primary>ts_debug</primary>
9768          </indexterm>
9769          <literal><function>ts_debug(<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[]</>)</function></literal>
9770         </entry>
9771         <entry><type>setof record</type></entry>
9772         <entry>test a configuration</entry>
9773         <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
9774         <entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
9775        </row>
9776        <row>
9777         <entry>
9778          <indexterm>
9779           <primary>ts_lexize</primary>
9780          </indexterm>
9781          <literal><function>ts_lexize(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</function></literal>
9782         </entry>
9783         <entry><type>text[]</type></entry>
9784         <entry>test a dictionary</entry>
9785         <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
9786         <entry><literal>{star}</literal></entry>
9787        </row>
9788        <row>
9789         <entry>
9790          <indexterm>
9791           <primary>ts_parse</primary>
9792          </indexterm>
9793          <literal><function>ts_parse(<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</>)</function></literal>
9794         </entry>
9795         <entry><type>setof record</type></entry>
9796         <entry>test a parser</entry>
9797         <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
9798         <entry><literal>(1,foo) ...</literal></entry>
9799        </row>
9800        <row>
9801         <entry><literal><function>ts_parse(<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</>)</function></literal></entry>
9802         <entry><type>setof record</type></entry>
9803         <entry>test a parser</entry>
9804         <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
9805         <entry><literal>(1,foo) ...</literal></entry>
9806        </row>
9807        <row>
9808         <entry>
9809          <indexterm>
9810           <primary>ts_token_type</primary>
9811          </indexterm>
9812          <literal><function>ts_token_type(<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</>)</function></literal>
9813         </entry>
9814         <entry><type>setof record</type></entry>
9815         <entry>get token types defined by parser</entry>
9816         <entry><literal>ts_token_type('default')</literal></entry>
9817         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
9818        </row>
9819        <row>
9820         <entry><literal><function>ts_token_type(<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</>)</function></literal></entry>
9821         <entry><type>setof record</type></entry>
9822         <entry>get token types defined by parser</entry>
9823         <entry><literal>ts_token_type(3722)</literal></entry>
9824         <entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
9825        </row>
9826        <row>
9827         <entry>
9828          <indexterm>
9829           <primary>ts_stat</primary>
9830          </indexterm>
9831          <literal><function>ts_stat(<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</>)</function></literal>
9832         </entry>
9833         <entry><type>setof record</type></entry>
9834         <entry>get statistics of a <type>tsvector</> column</entry>
9835         <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
9836         <entry><literal>(foo,10,15) ...</literal></entry>
9837        </row>
9838       </tbody>
9839      </tgroup>
9840     </table>
9841
9842  </sect1>
9843
9844
9845  <sect1 id="functions-xml">
9846   <title>XML Functions</title>
9847
9848   <para>
9849    The functions and function-like expressions described in this
9850    section operate on values of type <type>xml</type>.  Check <xref
9851    linkend="datatype-xml"> for information about the <type>xml</type>
9852    type.  The function-like expressions <function>xmlparse</function>
9853    and <function>xmlserialize</function> for converting to and from
9854    type <type>xml</type> are not repeated here.  Use of most of these
9855    functions requires the installation to have been built
9856    with <command>configure --with-libxml</>.
9857   </para>
9858
9859   <sect2 id="functions-producing-xml">
9860    <title>Producing XML Content</title>
9861
9862    <para>
9863     A set of functions and function-like expressions are available for
9864     producing XML content from SQL data.  As such, they are
9865     particularly suitable for formatting query results into XML
9866     documents for processing in client applications.
9867    </para>
9868
9869    <sect3>
9870     <title><literal>xmlcomment</literal></title>
9871
9872     <indexterm>
9873      <primary>xmlcomment</primary>
9874     </indexterm>
9875
9876 <synopsis>
9877 <function>xmlcomment</function>(<replaceable>text</replaceable>)
9878 </synopsis>
9879
9880     <para>
9881      The function <function>xmlcomment</function> creates an XML value
9882      containing an XML comment with the specified text as content.
9883      The text cannot contain <quote><literal>--</literal></quote> or end with a
9884      <quote><literal>-</literal></quote> so that the resulting construct is a valid
9885      XML comment.  If the argument is null, the result is null.
9886     </para>
9887
9888     <para>
9889      Example:
9890 <screen><![CDATA[
9891 SELECT xmlcomment('hello');
9892
9893   xmlcomment
9894 --------------
9895  <!--hello-->
9896 ]]></screen>
9897     </para>
9898    </sect3>
9899
9900    <sect3>
9901     <title><literal>xmlconcat</literal></title>
9902
9903     <indexterm>
9904      <primary>xmlconcat</primary>
9905     </indexterm>
9906
9907 <synopsis>
9908 <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
9909 </synopsis>
9910
9911     <para>
9912      The function <function>xmlconcat</function> concatenates a list
9913      of individual XML values to create a single value containing an
9914      XML content fragment.  Null values are omitted; the result is
9915      only null if there are no nonnull arguments.
9916     </para>
9917
9918     <para>
9919      Example:
9920 <screen><![CDATA[
9921 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
9922
9923       xmlconcat
9924 ----------------------
9925  <abc/><bar>foo</bar>
9926 ]]></screen>
9927     </para>
9928
9929     <para>
9930      XML declarations, if present, are combined as follows.  If all
9931      argument values have the same XML version declaration, that
9932      version is used in the result, else no version is used.  If all
9933      argument values have the standalone declaration value
9934      <quote>yes</quote>, then that value is used in the result.  If
9935      all argument values have a standalone declaration value and at
9936      least one is <quote>no</quote>, then that is used in the result.
9937      Else the result will have no standalone declaration.  If the
9938      result is determined to require a standalone declaration but no
9939      version declaration, a version declaration with version 1.0 will
9940      be used because XML requires an XML declaration to contain a
9941      version declaration.  Encoding declarations are ignored and
9942      removed in all cases.
9943     </para>
9944
9945     <para>
9946      Example:
9947 <screen><![CDATA[
9948 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
9949
9950              xmlconcat
9951 -----------------------------------
9952  <?xml version="1.1"?><foo/><bar/>
9953 ]]></screen>
9954     </para>
9955    </sect3>
9956
9957    <sect3>
9958     <title><literal>xmlelement</literal></title>
9959
9960    <indexterm>
9961     <primary>xmlelement</primary>
9962    </indexterm>
9963
9964 <synopsis>
9965 <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>)
9966 </synopsis>
9967
9968     <para>
9969      The <function>xmlelement</function> expression produces an XML
9970      element with the given name, attributes, and content.
9971     </para>
9972
9973     <para>
9974      Examples:
9975 <screen><![CDATA[
9976 SELECT xmlelement(name foo);
9977
9978  xmlelement
9979 ------------
9980  <foo/>
9981
9982 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
9983
9984     xmlelement
9985 ------------------
9986  <foo bar="xyz"/>
9987
9988 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
9989
9990              xmlelement
9991 -------------------------------------
9992  <foo bar="2007-01-26">content</foo>
9993 ]]></screen>
9994     </para>
9995
9996     <para>
9997      Element and attribute names that are not valid XML names are
9998      escaped by replacing the offending characters by the sequence
9999      <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
10000      <replaceable>HHHH</replaceable> is the character's Unicode
10001      codepoint in hexadecimal notation.  For example:
10002 <screen><![CDATA[
10003 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
10004
10005             xmlelement
10006 ----------------------------------
10007  <foo_x0024_bar a_x0026_b="xyz"/>
10008 ]]></screen>
10009     </para>
10010
10011     <para>
10012      An explicit attribute name need not be specified if the attribute
10013      value is a column reference, in which case the column's name will
10014      be used as the attribute name by default.  In other cases, the
10015      attribute must be given an explicit name.  So this example is
10016      valid:
10017 <screen>
10018 CREATE TABLE test (a xml, b xml);
10019 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
10020 </screen>
10021      But these are not:
10022 <screen>
10023 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
10024 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
10025 </screen>
10026     </para>
10027
10028     <para>
10029      Element content, if specified, will be formatted according to
10030      its data type.  If the content is itself of type <type>xml</type>,
10031      complex XML documents can be constructed.  For example:
10032 <screen><![CDATA[
10033 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
10034                             xmlelement(name abc),
10035                             xmlcomment('test'),
10036                             xmlelement(name xyz));
10037
10038                   xmlelement
10039 ----------------------------------------------
10040  <foo bar="xyz"><abc/><!--test--><xyz/></foo>
10041 ]]></screen>
10042
10043      Content of other types will be formatted into valid XML character
10044      data.  This means in particular that the characters &lt;, &gt;,
10045      and &amp; will be converted to entities.  Binary data (data type
10046      <type>bytea</type>) will be represented in base64 or hex
10047      encoding, depending on the setting of the configuration parameter
10048      <xref linkend="guc-xmlbinary">.  The particular behavior for
10049      individual data types is expected to evolve in order to align the
10050      SQL and PostgreSQL data types with the XML Schema specification,
10051      at which point a more precise description will appear.
10052     </para>
10053    </sect3>
10054
10055    <sect3>
10056     <title><literal>xmlforest</literal></title>
10057
10058    <indexterm>
10059     <primary>xmlforest</primary>
10060    </indexterm>
10061
10062 <synopsis>
10063 <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
10064 </synopsis>
10065
10066     <para>
10067      The <function>xmlforest</function> expression produces an XML
10068      forest (sequence) of elements using the given names and content.
10069     </para>
10070
10071     <para>
10072      Examples:
10073 <screen><![CDATA[
10074 SELECT xmlforest('abc' AS foo, 123 AS bar);
10075
10076           xmlforest
10077 ------------------------------
10078  <foo>abc</foo><bar>123</bar>
10079
10080
10081 SELECT xmlforest(table_name, column_name)
10082 FROM information_schema.columns
10083 WHERE table_schema = 'pg_catalog';
10084
10085                                          xmlforest
10086 -------------------------------------------------------------------------------------------
10087  <table_name>pg_authid</table_name><column_name>rolname</column_name>
10088  <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
10089  ...
10090 ]]></screen>
10091
10092      As seen in the second example, the element name can be omitted if
10093      the content value is a column reference, in which case the column
10094      name is used by default.  Otherwise, a name must be specified.
10095     </para>
10096
10097     <para>
10098      Element names that are not valid XML names are escaped as shown
10099      for <function>xmlelement</function> above.  Similarly, content
10100      data is escaped to make valid XML content, unless it is already
10101      of type <type>xml</type>.
10102     </para>
10103
10104     <para>
10105      Note that XML forests are not valid XML documents if they consist
10106      of more than one element, so it might be useful to wrap
10107      <function>xmlforest</function> expressions in
10108      <function>xmlelement</function>.
10109     </para>
10110    </sect3>
10111
10112    <sect3>
10113     <title><literal>xmlpi</literal></title>
10114
10115    <indexterm>
10116     <primary>xmlpi</primary>
10117    </indexterm>
10118
10119 <synopsis>
10120 <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
10121 </synopsis>
10122
10123     <para>
10124      The <function>xmlpi</function> expression creates an XML
10125      processing instruction.  The content, if present, must not
10126      contain the character sequence <literal>?&gt;</literal>.
10127     </para>
10128
10129     <para>
10130      Example:
10131 <screen><![CDATA[
10132 SELECT xmlpi(name php, 'echo "hello world";');
10133
10134             xmlpi
10135 -----------------------------
10136  <?php echo "hello world";?>
10137 ]]></screen>
10138     </para>
10139    </sect3>
10140
10141    <sect3>
10142     <title><literal>xmlroot</literal></title>
10143
10144    <indexterm>
10145     <primary>xmlroot</primary>
10146    </indexterm>
10147
10148 <synopsis>
10149 <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
10150 </synopsis>
10151
10152     <para>
10153      The <function>xmlroot</function> expression alters the properties
10154      of the root node of an XML value.  If a version is specified,
10155      it replaces the value in the root node's version declaration; if a
10156      standalone setting is specified, it replaces the value in the
10157      root node's standalone declaration.
10158     </para>
10159
10160     <para>
10161 <screen><![CDATA[
10162 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
10163                version '1.0', standalone yes);
10164
10165                 xmlroot
10166 ----------------------------------------
10167  <?xml version="1.0" standalone="yes"?>
10168  <content>abc</content>
10169 ]]></screen>
10170     </para>
10171    </sect3>
10172
10173    <sect3 id="functions-xml-xmlagg">
10174     <title><literal>xmlagg</literal></title>
10175
10176     <indexterm>
10177      <primary>xmlagg</primary>
10178     </indexterm>
10179
10180 <synopsis>
10181 <function>xmlagg</function>(<replaceable>xml</replaceable>)
10182 </synopsis>
10183
10184     <para>
10185      The function <function>xmlagg</function> is, unlike the other
10186      functions described here, an aggregate function.  It concatenates the
10187      input values to the aggregate function call,
10188      much like <function>xmlconcat</function> does, except that concatenation
10189      occurs across rows rather than across expressions in a single row.
10190      See <xref linkend="functions-aggregate"> for additional information
10191      about aggregate functions.
10192     </para>
10193
10194     <para>
10195      Example:
10196 <screen><![CDATA[
10197 CREATE TABLE test (y int, x xml);
10198 INSERT INTO test VALUES (1, '<foo>abc</foo>');
10199 INSERT INTO test VALUES (2, '<bar/>');
10200 SELECT xmlagg(x) FROM test;
10201         xmlagg
10202 ----------------------
10203  <foo>abc</foo><bar/>
10204 ]]></screen>
10205     </para>
10206
10207     <para>
10208      To determine the order of the concatenation, an <literal>ORDER BY</>
10209      clause may be added to the aggregate call as described in
10210      <xref linkend="syntax-aggregates">. For example:
10211
10212 <screen><![CDATA[
10213 SELECT xmlagg(x ORDER BY y DESC) FROM test;
10214         xmlagg
10215 ----------------------
10216  <bar/><foo>abc</foo>
10217 ]]></screen>
10218     </para>
10219
10220     <para>
10221      The following non-standard approach used to be recommended
10222      in previous versions, and may still be useful in specific
10223      cases:
10224
10225 <screen><![CDATA[
10226 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
10227         xmlagg
10228 ----------------------
10229  <bar/><foo>abc</foo>
10230 ]]></screen>
10231     </para>
10232    </sect3>
10233    </sect2>
10234
10235    <sect2 id="functions-xml-predicates">
10236     <title>XML Predicates</title>
10237
10238     <para>
10239      The expressions described in this section check properties
10240      of <type>xml</type> values.
10241     </para>
10242
10243    <sect3>
10244     <title><literal>IS DOCUMENT</literal></title>
10245
10246     <indexterm>
10247      <primary>IS DOCUMENT</primary>
10248     </indexterm>
10249
10250 <synopsis>
10251 <replaceable>xml</replaceable> IS DOCUMENT
10252 </synopsis>
10253
10254     <para>
10255      The expression <literal>IS DOCUMENT</literal> returns true if the
10256      argument XML value is a proper XML document, false if it is not
10257      (that is, it is a content fragment), or null if the argument is
10258      null.  See <xref linkend="datatype-xml"> about the difference
10259      between documents and content fragments.
10260     </para>
10261    </sect3>
10262
10263    <sect3 id="xml-exists">
10264     <title><literal>XMLEXISTS</literal></title>
10265
10266     <indexterm>
10267      <primary>XMLEXISTS</primary>
10268     </indexterm>
10269
10270 <synopsis>
10271 <function>XMLEXISTS</function>(<replaceable>text</replaceable> PASSING <optional>BY REF</optional> <replaceable>xml</replaceable> <optional>BY REF</optional>)
10272 </synopsis>
10273
10274     <para>
10275      The function <function>xmlexists</function> returns true if the
10276      XPath expression in the first argument returns any nodes, and
10277      false otherwise.  (If either argument is null, the result is
10278      null.)
10279     </para>
10280
10281     <para>
10282      Example:
10283      <screen><![CDATA[
10284 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY REF '<towns><town>Toronto</town><town>Ottawa</town></towns>');
10285
10286  xmlexists
10287 ------------
10288  t
10289 (1 row)
10290 ]]></screen>
10291     </para>
10292
10293     <para>
10294      The <literal>BY REF</literal> clauses have no effect in
10295      PostgreSQL, but are allowed for SQL conformance and compatibility
10296      with other implementations.  Per SQL standard, the
10297      first <literal>BY REF</literal> is required, the second is
10298      optional.  Also note that the SQL standard specifies
10299      the <function>xmlexists</function> construct to take an XQuery
10300      expression as first argument, but PostgreSQL currently only
10301      supports XPath, which is a subset of XQuery.
10302     </para>
10303    </sect3>
10304
10305    <sect3 id="xml-is-well-formed">
10306     <title><literal>xml_is_well_formed</literal></title>
10307
10308     <indexterm>
10309      <primary>xml_is_well_formed</primary>
10310     </indexterm>
10311
10312     <indexterm>
10313      <primary>xml_is_well_formed_document</primary>
10314     </indexterm>
10315
10316     <indexterm>
10317      <primary>xml_is_well_formed_content</primary>
10318     </indexterm>
10319
10320 <synopsis>
10321 <function>xml_is_well_formed</function>(<replaceable>text</replaceable>)
10322 <function>xml_is_well_formed_document</function>(<replaceable>text</replaceable>)
10323 <function>xml_is_well_formed_content</function>(<replaceable>text</replaceable>)
10324 </synopsis>
10325
10326     <para>
10327      These functions check whether a <type>text</> string is well-formed XML,
10328      returning a Boolean result.
10329      <function>xml_is_well_formed_document</function> checks for a well-formed
10330      document, while <function>xml_is_well_formed_content</function> checks
10331      for well-formed content.  <function>xml_is_well_formed</function> does
10332      the former if the <xref linkend="guc-xmloption"> configuration
10333      parameter is set to <literal>DOCUMENT</>, or the latter if it is set to
10334      <literal>CONTENT</>.  This means that
10335      <function>xml_is_well_formed</function> is useful for seeing whether
10336      a simple cast to type <type>xml</> will succeed, whereas the other two
10337      functions are useful for seeing whether the corresponding variants of
10338      <function>XMLPARSE</> will succeed.
10339     </para>
10340
10341     <para>
10342      Examples:
10343
10344 <screen><![CDATA[
10345 SET xmloption TO DOCUMENT;
10346 SELECT xml_is_well_formed('<>');
10347  xml_is_well_formed 
10348 --------------------
10349  f
10350 (1 row)
10351
10352 SELECT xml_is_well_formed('<abc/>');
10353  xml_is_well_formed 
10354 --------------------
10355  t
10356 (1 row)
10357
10358 SET xmloption TO CONTENT;
10359 SELECT xml_is_well_formed('abc');
10360  xml_is_well_formed 
10361 --------------------
10362  t
10363 (1 row)
10364
10365 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
10366  xml_is_well_formed_document 
10367 -----------------------------
10368  t
10369 (1 row)
10370
10371 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
10372  xml_is_well_formed_document 
10373 -----------------------------
10374  f
10375 (1 row)
10376 ]]></screen>
10377
10378      The last example shows that the checks include whether
10379      namespaces are correctly matched.
10380     </para>
10381    </sect3>
10382   </sect2>
10383
10384   <sect2 id="functions-xml-processing">
10385    <title>Processing XML</title>
10386
10387    <para>
10388     To process values of data type <type>xml</type>, PostgreSQL offers
10389     the functions <function>xpath</function> and
10390     <function>xpath_exists</function>, which evaluate XPath 1.0
10391     expressions, and the <function>XMLTABLE</function>
10392     table function.
10393    </para>
10394
10395    <sect3 id="functions-xml-processing-xpath">
10396     <title><literal>xpath</literal></title>
10397
10398     <indexterm>
10399      <primary>XPath</primary>
10400     </indexterm>
10401
10402 <synopsis>
10403 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
10404 </synopsis>
10405
10406     <para>
10407      The function <function>xpath</function> evaluates the XPath
10408      expression <replaceable>xpath</replaceable> (a <type>text</> value)
10409      against the XML value
10410      <replaceable>xml</replaceable>.  It returns an array of XML values
10411      corresponding to the node set produced by the XPath expression.
10412      If the XPath expression returns a scalar value rather than a node set,
10413      a single-element array is returned.
10414     </para>
10415
10416     <para>
10417      The second argument must be a well formed XML document. In particular,
10418      it must have a single root node element.
10419     </para>
10420
10421     <para>
10422      The optional third argument of the function is an array of namespace
10423      mappings.  This array should be a two-dimensional <type>text</> array with
10424      the length of the second axis being equal to 2 (i.e., it should be an
10425      array of arrays, each of which consists of exactly 2 elements).
10426      The first element of each array entry is the namespace name (alias), the
10427      second the namespace URI. It is not required that aliases provided in
10428      this array be the same as those being used in the XML document itself (in
10429      other words, both in the XML document and in the <function>xpath</function>
10430      function context, aliases are <emphasis>local</>).
10431     </para>
10432
10433     <para>
10434      Example:
10435 <screen><![CDATA[
10436 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
10437              ARRAY[ARRAY['my', 'http://example.com']]);
10438
10439  xpath  
10440 --------
10441  {test}
10442 (1 row)
10443 ]]></screen>
10444     </para>
10445
10446     <para>
10447      To deal with default (anonymous) namespaces, do something like this:
10448 <screen><![CDATA[
10449 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
10450              ARRAY[ARRAY['mydefns', 'http://example.com']]);
10451
10452  xpath
10453 --------
10454  {test}
10455 (1 row)
10456 ]]></screen>
10457     </para>
10458    </sect3>
10459
10460    <sect3 id="functions-xml-processing-xpath-exists">
10461     <title><literal>xpath_exists</literal></title>
10462
10463     <indexterm>
10464      <primary>xpath_exists</primary>
10465     </indexterm>
10466
10467 <synopsis>
10468 <function>xpath_exists</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
10469 </synopsis>
10470
10471     <para>
10472      The function <function>xpath_exists</function> is a specialized form
10473      of the <function>xpath</function> function.  Instead of returning the
10474      individual XML values that satisfy the XPath, this function returns a
10475      Boolean indicating whether the query was satisfied or not.  This
10476      function is equivalent to the standard <literal>XMLEXISTS</> predicate,
10477      except that it also offers support for a namespace mapping argument.
10478     </para>
10479
10480     <para>
10481      Example:
10482 <screen><![CDATA[
10483 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
10484                      ARRAY[ARRAY['my', 'http://example.com']]);
10485
10486  xpath_exists  
10487 --------------
10488  t
10489 (1 row)
10490 ]]></screen>
10491     </para>
10492    </sect3>
10493
10494    <sect3 id="functions-xml-processing-xmltable">
10495     <title><literal>xmltable</literal></title>
10496
10497     <indexterm>
10498      <primary>xmltable</primary>
10499     </indexterm>
10500
10501     <indexterm zone="functions-xml-processing-xmltable">
10502      <primary>table function</primary>
10503      <secondary>XMLTABLE</secondary>
10504     </indexterm>
10505
10506 <synopsis>
10507 <function>xmltable</function>( <optional>XMLNAMESPACES(<replaceable>namespace uri</replaceable> AS <replaceable>namespace name</replaceable><optional>, ...</optional>)</optional>
10508           <replaceable>row_expression</replaceable> PASSING <optional>BY REF</optional> <replaceable>document_expression</replaceable> <optional>BY REF</optional>
10509           COLUMNS <replaceable>name</replaceable> { <replaceable>type</replaceable> <optional>PATH <replaceable>column_expression</replaceable></optional> <optional>DEFAULT <replaceable>default_expression</replaceable></optional> <optional>NOT NULL | NULL</optional>
10510                         | FOR ORDINALITY }
10511                    <optional>, ...</optional>
10512 )
10513 </synopsis>
10514
10515     <para>
10516      The <function>xmltable</function> function produces a table based
10517      on the given XML value, an XPath filter to extract rows, and an
10518      optional set of column definitions.
10519     </para>
10520
10521     <para>
10522      The optional <literal>XMLNAMESPACES</> clause is a comma-separated
10523      list of namespaces.  It specifies the XML namespaces used in
10524      the document and their aliases. A default namespace specification
10525      is not currently supported.
10526     </para>
10527
10528     <para>
10529      The required <replaceable>row_expression</> argument is an XPath
10530      expression that is evaluated against the supplied XML document to
10531      obtain an ordered sequence of XML nodes. This sequence is what
10532      <function>xmltable</> transforms into output rows.
10533     </para>
10534
10535     <para>
10536      <replaceable>document_expression</> provides the XML document to
10537      operate on.
10538      The <literal>BY REF</literal> clauses have no effect in PostgreSQL,
10539      but are allowed for SQL conformance and compatibility with other
10540      implementations.
10541      The argument must be a well-formed XML document; fragments/forests
10542      are not accepted.
10543     </para>
10544
10545     <para>
10546      The mandatory <literal>COLUMNS</literal> clause specifies the list
10547      of columns in the output table.
10548      If the <literal>COLUMNS</> clause is omitted, the rows in the result
10549      set contain a single column of type <literal>xml</> containing the
10550      data matched by <replaceable>row_expression</>.
10551      If <literal>COLUMNS</literal> is specified, each entry describes a
10552      single column.
10553      See the syntax summary above for the format.
10554      The column name and type are required; the path, default and
10555      nullability clauses are optional.
10556     </para>
10557
10558     <para>
10559      A column marked <literal>FOR ORDINALITY</literal> will be populated
10560      with row numbers matching the order in which the
10561      output rows appeared in the original input XML document.
10562      At most one column may be marked <literal>FOR ORDINALITY</literal>.
10563     </para>
10564
10565     <para>
10566      The <literal>column_expression</> for a column is an XPath expression
10567      that is evaluated for each row, relative to the result of the
10568      <replaceable>row_expression</>, to find the value of the column.
10569      If no <literal>column_expression</> is given, then the column name
10570      is used as an implicit path.
10571     </para>
10572
10573     <para>
10574      If a column's XPath expression returns multiple elements, an error
10575      is raised.
10576      If the expression matches an empty tag, the result is an
10577      empty string (not <literal>NULL</>).
10578      Any <literal>xsi:nil</> attributes are ignored.
10579     </para>
10580
10581     <para>
10582      The text body of the XML matched by the <replaceable>column_expression</>
10583      is used as the column value. Multiple <literal>text()</literal> nodes
10584      within an element are concatenated in order. Any child elements,
10585      processing instructions, and comments are ignored, but the text contents
10586      of child elements are concatenated to the result.
10587      Note that the whitespace-only <literal>text()</> node between two non-text
10588      elements is preserved, and that leading whitespace on a <literal>text()</>
10589      node is not flattened.
10590     </para>
10591
10592     <para>
10593      If the path expression does not match for a given row but
10594      <replaceable>default_expression</> is specified, the value resulting
10595      from evaluating that expression is used.
10596      If no <literal>DEFAULT</> clause is given for the column,
10597      the field will be set to <literal>NULL</>.
10598      It is possible for a <replaceable>default_expression</> to reference
10599      the value of output columns that appear prior to it in the column list,
10600      so the default of one column may be based on the value of another
10601      column.
10602     </para>
10603
10604     <para>
10605      Columns may be marked <literal>NOT NULL</>. If the
10606      <replaceable>column_expression</> for a <literal>NOT NULL</> column
10607      does not match anything and there is no <literal>DEFAULT</> or the
10608      <replaceable>default_expression</> also evaluates to null, an error
10609      is reported.
10610     </para>
10611
10612     <para>
10613      Unlike regular PostgreSQL functions, <replaceable>column_expression</>
10614      and <replaceable>default_expression</> are not evaluated to a simple
10615      value before calling the function.
10616      <replaceable>column_expression</> is normally evaluated
10617      exactly once per input row, and <replaceable>default_expression</>
10618      is evaluated each time a default is needed for a field.
10619      If the expression qualifies as stable or immutable the repeat
10620      evaluation may be skipped.
10621      Effectively <function>xmltable</> behaves more like a subquery than a
10622      function call.
10623      This means that you can usefully use volatile functions like
10624      <function>nextval</> in <replaceable>default_expression</>, and
10625      <replaceable>column_expression</> may depend on other parts of the
10626      XML document.
10627     </para>
10628
10629     <para>
10630      Examples:
10631   <screen><![CDATA[
10632 CREATE TABLE xmldata AS SELECT
10633 xml $$
10634 <ROWS>
10635   <ROW id="1">
10636     <COUNTRY_ID>AU</COUNTRY_ID>
10637     <COUNTRY_NAME>Australia</COUNTRY_NAME>
10638   </ROW>
10639   <ROW id="5">
10640     <COUNTRY_ID>JP</COUNTRY_ID>
10641     <COUNTRY_NAME>Japan</COUNTRY_NAME>
10642     <PREMIER_NAME>Shinzo Abe</PREMIER_NAME>
10643     <SIZE unit="sq_mi">145935</SIZE>
10644   </ROW>
10645   <ROW id="6">
10646     <COUNTRY_ID>SG</COUNTRY_ID>
10647     <COUNTRY_NAME>Singapore</COUNTRY_NAME>
10648     <SIZE unit="sq_km">697</SIZE>
10649   </ROW>
10650 </ROWS>
10651 $$ AS data;
10652
10653 SELECT xmltable.*
10654   FROM xmldata,
10655        XMLTABLE('//ROWS/ROW'
10656                 PASSING data
10657                 COLUMNS id int PATH '@id',
10658                         ordinality FOR ORDINALITY,
10659                         "COUNTRY_NAME" text,
10660                         country_id text PATH 'COUNTRY_ID',
10661                         size_sq_km float PATH 'SIZE[@unit = "sq_km"]',
10662                         size_other text PATH
10663                              'concat(SIZE[@unit!="sq_km"], " ", SIZE[@unit!="sq_km"]/@unit)',
10664                         premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified') ;
10665
10666  id | ordinality | COUNTRY_NAME | country_id | size_sq_km |  size_other  | premier_name  
10667 ----+------------+--------------+------------+------------+--------------+---------------
10668   1 |          1 | Australia    | AU         |            |              | not specified
10669   5 |          2 | Japan        | JP         |            | 145935 sq_mi | Shinzo Abe
10670   6 |          3 | Singapore    | SG         |        697 |              | not specified
10671 ]]></screen>
10672
10673      The following example shows concatenation of multiple text() nodes,
10674      usage of the column name as XPath filter, and the treatment of whitespace,
10675      XML comments and processing instructions:
10676
10677   <screen><![CDATA[
10678 CREATE TABLE xmlelements AS SELECT
10679 xml $$
10680   <root>
10681    <element>  Hello<!-- xyxxz -->2a2<?aaaaa?> <!--x-->  bbb<x>xxx</x>CC  </element>
10682   </root>
10683 $$ AS data;
10684
10685 SELECT xmltable.*
10686   FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text);
10687        element        
10688 ----------------------
10689    Hello2a2   bbbCC  
10690 ]]></screen>
10691     </para>
10692    </sect3>
10693   </sect2>
10694
10695   <sect2 id="functions-xml-mapping">
10696    <title>Mapping Tables to XML</title>
10697
10698    <indexterm zone="functions-xml-mapping">
10699     <primary>XML export</primary>
10700    </indexterm>
10701
10702    <para>
10703     The following functions map the contents of relational tables to
10704     XML values.  They can be thought of as XML export functionality:
10705 <synopsis>
10706 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
10707 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
10708 cursor_to_xml(cursor refcursor, count int, nulls boolean,
10709               tableforest boolean, targetns text)
10710 </synopsis>
10711     The return type of each function is <type>xml</type>.
10712    </para>
10713
10714    <para>
10715     <function>table_to_xml</function> maps the content of the named
10716     table, passed as parameter <parameter>tbl</parameter>.  The
10717     <type>regclass</type> type accepts strings identifying tables using the
10718     usual notation, including optional schema qualifications and
10719     double quotes.  <function>query_to_xml</function> executes the
10720     query whose text is passed as parameter
10721     <parameter>query</parameter> and maps the result set.
10722     <function>cursor_to_xml</function> fetches the indicated number of
10723     rows from the cursor specified by the parameter
10724     <parameter>cursor</parameter>.  This variant is recommended if
10725     large tables have to be mapped, because the result value is built
10726     up in memory by each function.
10727    </para>
10728
10729    <para>
10730     If <parameter>tableforest</parameter> is false, then the resulting
10731     XML document looks like this:
10732 <screen><![CDATA[
10733 <tablename>
10734   <row>
10735     <columnname1>data</columnname1>
10736     <columnname2>data</columnname2>
10737   </row>
10738
10739   <row>
10740     ...
10741   </row>
10742
10743   ...
10744 </tablename>
10745 ]]></screen>
10746
10747     If <parameter>tableforest</parameter> is true, the result is an
10748     XML content fragment that looks like this:
10749 <screen><![CDATA[
10750 <tablename>
10751   <columnname1>data</columnname1>
10752   <columnname2>data</columnname2>
10753 </tablename>
10754
10755 <tablename>
10756   ...
10757 </tablename>
10758
10759 ...
10760 ]]></screen>
10761
10762     If no table name is available, that is, when mapping a query or a
10763     cursor, the string <literal>table</literal> is used in the first
10764     format, <literal>row</literal> in the second format.
10765    </para>
10766
10767    <para>
10768     The choice between these formats is up to the user.  The first
10769     format is a proper XML document, which will be important in many
10770     applications.  The second format tends to be more useful in the
10771     <function>cursor_to_xml</function> function if the result values are to be
10772     reassembled into one document later on.  The functions for
10773     producing XML content discussed above, in particular
10774     <function>xmlelement</function>, can be used to alter the results
10775     to taste.
10776    </para>
10777
10778    <para>
10779     The data values are mapped in the same way as described for the
10780     function <function>xmlelement</function> above.
10781    </para>
10782
10783    <para>
10784     The parameter <parameter>nulls</parameter> determines whether null
10785     values should be included in the output.  If true, null values in
10786     columns are represented as:
10787 <screen><![CDATA[
10788 <columnname xsi:nil="true"/>
10789 ]]></screen>
10790     where <literal>xsi</literal> is the XML namespace prefix for XML
10791     Schema Instance.  An appropriate namespace declaration will be
10792     added to the result value.  If false, columns containing null
10793     values are simply omitted from the output.
10794    </para>
10795
10796    <para>
10797     The parameter <parameter>targetns</parameter> specifies the
10798     desired XML namespace of the result.  If no particular namespace
10799     is wanted, an empty string should be passed.
10800    </para>
10801
10802    <para>
10803     The following functions return XML Schema documents describing the
10804     mappings performed by the corresponding functions above:
10805 <synopsis>
10806 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
10807 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
10808 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
10809 </synopsis>
10810     It is essential that the same parameters are passed in order to
10811     obtain matching XML data mappings and XML Schema documents.
10812    </para>
10813
10814    <para>
10815     The following functions produce XML data mappings and the
10816     corresponding XML Schema in one document (or forest), linked
10817     together.  They can be useful where self-contained and
10818     self-describing results are wanted:
10819 <synopsis>
10820 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
10821 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
10822 </synopsis>
10823    </para>
10824
10825    <para>
10826     In addition, the following functions are available to produce
10827     analogous mappings of entire schemas or the entire current
10828     database:
10829 <synopsis>
10830 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
10831 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
10832 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
10833
10834 database_to_xml(nulls boolean, tableforest boolean, targetns text)
10835 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
10836 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
10837 </synopsis>
10838
10839     Note that these potentially produce a lot of data, which needs to
10840     be built up in memory.  When requesting content mappings of large
10841     schemas or databases, it might be worthwhile to consider mapping the
10842     tables separately instead, possibly even through a cursor.
10843    </para>
10844
10845    <para>
10846     The result of a schema content mapping looks like this:
10847
10848 <screen><![CDATA[
10849 <schemaname>
10850
10851 table1-mapping
10852
10853 table2-mapping
10854
10855 ...
10856
10857 </schemaname>]]></screen>
10858
10859     where the format of a table mapping depends on the
10860     <parameter>tableforest</parameter> parameter as explained above.
10861    </para>
10862
10863    <para>
10864     The result of a database content mapping looks like this:
10865
10866 <screen><![CDATA[
10867 <dbname>
10868
10869 <schema1name>
10870   ...
10871 </schema1name>
10872
10873 <schema2name>
10874   ...
10875 </schema2name>
10876
10877 ...
10878
10879 </dbname>]]></screen>
10880
10881     where the schema mapping is as above.
10882    </para>
10883
10884    <para>
10885     As an example of using the output produced by these functions,
10886     <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
10887     converts the output of
10888     <function>table_to_xml_and_xmlschema</function> to an HTML
10889     document containing a tabular rendition of the table data.  In a
10890     similar manner, the results from these functions can be
10891     converted into other XML-based formats.
10892    </para>
10893
10894    <figure id="xslt-xml-html">
10895     <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
10896 <programlisting><![CDATA[
10897 <?xml version="1.0"?>
10898 <xsl:stylesheet version="1.0"
10899     xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
10900     xmlns:xsd="http://www.w3.org/2001/XMLSchema"
10901     xmlns="http://www.w3.org/1999/xhtml"
10902 >
10903
10904   <xsl:output method="xml"
10905       doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
10906       doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
10907       indent="yes"/>
10908
10909   <xsl:template match="/*">
10910     <xsl:variable name="schema" select="//xsd:schema"/>
10911     <xsl:variable name="tabletypename"
10912                   select="$schema/xsd:element[@name=name(current())]/@type"/>
10913     <xsl:variable name="rowtypename"
10914                   select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
10915
10916     <html>
10917       <head>
10918         <title><xsl:value-of select="name(current())"/></title>
10919       </head>
10920       <body>
10921         <table>
10922           <tr>
10923             <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
10924               <th><xsl:value-of select="."/></th>
10925             </xsl:for-each>
10926           </tr>
10927
10928           <xsl:for-each select="row">
10929             <tr>
10930               <xsl:for-each select="*">
10931                 <td><xsl:value-of select="."/></td>
10932               </xsl:for-each>
10933             </tr>
10934           </xsl:for-each>
10935         </table>
10936       </body>
10937     </html>
10938   </xsl:template>
10939
10940 </xsl:stylesheet>
10941 ]]></programlisting>
10942    </figure>
10943   </sect2>
10944  </sect1>
10945
10946  <sect1 id="functions-json">
10947   <title>JSON Functions and Operators</title>
10948
10949   <indexterm zone="functions-json">
10950     <primary>JSON</primary>
10951     <secondary>functions and operators</secondary>
10952   </indexterm>
10953
10954    <para>
10955    <xref linkend="functions-json-op-table"> shows the operators that
10956    are available for use with the two JSON data types (see <xref
10957    linkend="datatype-json">).
10958   </para>
10959
10960   <table id="functions-json-op-table">
10961      <title><type>json</> and <type>jsonb</> Operators</title>
10962      <tgroup cols="5">
10963       <thead>
10964        <row>
10965         <entry>Operator</entry>
10966         <entry>Right Operand Type</entry>
10967         <entry>Description</entry>
10968         <entry>Example</entry>
10969         <entry>Example Result</entry>
10970        </row>
10971       </thead>
10972       <tbody>
10973        <row>
10974         <entry><literal>-&gt;</literal></entry>
10975         <entry><type>int</type></entry>
10976         <entry>Get JSON array element (indexed from zero, negative
10977         integers count from the end)</entry>
10978         <entry><literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json-&gt;2</literal></entry>
10979         <entry><literal>{"c":"baz"}</literal></entry>
10980        </row>
10981        <row>
10982         <entry><literal>-&gt;</literal></entry>
10983         <entry><type>text</type></entry>
10984         <entry>Get JSON object field by key</entry>
10985         <entry><literal>'{"a": {"b":"foo"}}'::json-&gt;'a'</literal></entry>
10986         <entry><literal>{"b":"foo"}</literal></entry>
10987        </row>
10988         <row>
10989         <entry><literal>-&gt;&gt;</literal></entry>
10990         <entry><type>int</type></entry>
10991         <entry>Get JSON array element as <type>text</></entry>
10992         <entry><literal>'[1,2,3]'::json-&gt;&gt;2</literal></entry>
10993         <entry><literal>3</literal></entry>
10994        </row>
10995        <row>
10996         <entry><literal>-&gt;&gt;</literal></entry>
10997         <entry><type>text</type></entry>
10998         <entry>Get JSON object field as <type>text</></entry>
10999         <entry><literal>'{"a":1,"b":2}'::json-&gt;&gt;'b'</literal></entry>
11000         <entry><literal>2</literal></entry>
11001        </row>
11002        <row>
11003         <entry><literal>#&gt;</literal></entry>
11004         <entry><type>text[]</type></entry>
11005         <entry>Get JSON object at specified path</entry>
11006         <entry><literal>'{"a": {"b":{"c": "foo"}}}'::json#&gt;'{a,b}'</literal></entry>
11007         <entry><literal>{"c": "foo"}</literal></entry>
11008        </row>
11009        <row>
11010         <entry><literal>#&gt;&gt;</literal></entry>
11011         <entry><type>text[]</type></entry>
11012         <entry>Get JSON object at specified path as <type>text</></entry>
11013         <entry><literal>'{"a":[1,2,3],"b":[4,5,6]}'::json#&gt;&gt;'{a,2}'</literal></entry>
11014         <entry><literal>3</literal></entry>
11015        </row>
11016       </tbody>
11017      </tgroup>
11018    </table>
11019
11020   <note>
11021    <para>
11022     There are parallel variants of these operators for both the
11023     <type>json</type> and <type>jsonb</type> types.
11024     The field/element/path extraction operators
11025     return the same type as their left-hand input (either <type>json</type>
11026     or <type>jsonb</type>), except for those specified as
11027     returning <type>text</>, which coerce the value to text.
11028     The field/element/path extraction operators return NULL, rather than
11029     failing, if the JSON input does not have the right structure to match
11030     the request; for example if no such element exists.  The
11031     field/element/path extraction operators that accept integer JSON
11032     array subscripts all support negative subscripting from the end of
11033     arrays.
11034    </para>
11035   </note>
11036   <para>
11037    The standard comparison operators shown in  <xref
11038    linkend="functions-comparison-op-table"> are available for
11039    <type>jsonb</type>, but not for <type>json</type>. They follow the
11040    ordering rules for B-tree operations outlined at <xref
11041    linkend="json-indexing">.
11042   </para>
11043   <para>
11044    Some further operators also exist only for <type>jsonb</type>, as shown
11045    in <xref linkend="functions-jsonb-op-table">.
11046    Many of these operators can be indexed by
11047    <type>jsonb</> operator classes.  For a full description of
11048    <type>jsonb</> containment and existence semantics, see <xref
11049    linkend="json-containment">.  <xref linkend="json-indexing">
11050    describes how these operators can be used to effectively index
11051    <type>jsonb</> data.
11052   </para>
11053   <table id="functions-jsonb-op-table">
11054      <title>Additional <type>jsonb</> Operators</title>
11055      <tgroup cols="4">
11056       <thead>
11057        <row>
11058         <entry>Operator</entry>
11059         <entry>Right Operand Type</entry>
11060         <entry>Description</entry>
11061         <entry>Example</entry>
11062        </row>
11063       </thead>
11064       <tbody>
11065        <row>
11066         <entry><literal>@&gt;</literal></entry>
11067         <entry><type>jsonb</type></entry>
11068         <entry>Does the left JSON value contain the right JSON
11069         path/value entries at the top level?</entry>
11070         <entry><literal>'{"a":1, "b":2}'::jsonb &#64;&gt; '{"b":2}'::jsonb</literal></entry>
11071        </row>
11072        <row>
11073         <entry><literal>&lt;@</literal></entry>
11074         <entry><type>jsonb</type></entry>
11075         <entry>Are the left JSON path/value entries contained at the top level within
11076         the right JSON value?</entry>
11077         <entry><literal>'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</literal></entry>
11078        </row>
11079        <row>
11080         <entry><literal>?</literal></entry>
11081         <entry><type>text</type></entry>
11082         <entry>Does the <emphasis>string</emphasis> exist as a top-level
11083         key within the JSON value?</entry>
11084         <entry><literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal></entry>
11085        </row>
11086        <row>
11087         <entry><literal>?|</literal></entry>
11088         <entry><type>text[]</type></entry>
11089         <entry>Do any of these array <emphasis>strings</emphasis>
11090         exist as top-level keys?</entry>
11091         <entry><literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'c']</literal></entry>
11092        </row>
11093        <row>
11094         <entry><literal>?&amp;</literal></entry>
11095         <entry><type>text[]</type></entry>
11096         <entry>Do all of these array <emphasis>strings</emphasis> exist
11097         as top-level keys?</entry>
11098         <entry><literal>'["a", "b"]'::jsonb ?&amp; array['a', 'b']</literal></entry>
11099        </row>
11100        <row>
11101         <entry><literal>||</literal></entry>
11102         <entry><type>jsonb</type></entry>
11103         <entry>Concatenate two <type>jsonb</type> values into a new <type>jsonb</type> value</entry>
11104         <entry><literal>'["a", "b"]'::jsonb || '["c", "d"]'::jsonb</literal></entry>
11105        </row>
11106        <row>
11107         <entry><literal>-</literal></entry>
11108         <entry><type>text</type></entry>
11109         <entry>Delete key/value pair or <emphasis>string</emphasis>
11110         element from left operand.  Key/value pairs are matched based
11111         on their key value.</entry>
11112         <entry><literal>'{"a": "b"}'::jsonb - 'a' </literal></entry>
11113        </row>
11114        <row>
11115         <entry><literal>-</literal></entry>
11116         <entry><type>text[]</type></entry>
11117         <entry>Delete multiple key/value pairs or <emphasis>string</emphasis>
11118         elements from left operand.  Key/value pairs are matched based
11119         on their key value.</entry>
11120         <entry><literal>'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[] </literal></entry>
11121        </row>
11122        <row>
11123         <entry><literal>-</literal></entry>
11124         <entry><type>integer</type></entry>
11125         <entry>Delete the array element with specified index (Negative
11126         integers count from the end).  Throws an error if top level
11127         container is not an array.</entry>
11128         <entry><literal>'["a", "b"]'::jsonb - 1 </literal></entry>
11129        </row>
11130        <row>
11131         <entry><literal>#-</literal></entry>
11132         <entry><type>text[]</type></entry>
11133         <entry>Delete the field or element with specified path (for
11134         JSON arrays, negative integers count from the end)</entry>
11135         <entry><literal>'["a", {"b":1}]'::jsonb #- '{1,b}'</literal></entry>
11136        </row>
11137       </tbody>
11138      </tgroup>
11139    </table>
11140
11141   <note>
11142    <para>
11143     The <literal>||</> operator concatenates the elements at the top level of
11144     each of its operands. It does not operate recursively. For example, if
11145     both operands are objects with a common key field name, the value of the
11146     field in the result will just be the value from the right hand operand.
11147    </para>
11148   </note>
11149
11150   <para>
11151    <xref linkend="functions-json-creation-table"> shows the functions that are
11152    available for creating <type>json</type> and <type>jsonb</type> values.
11153    (There are no equivalent functions for <type>jsonb</>, of the <literal>row_to_json</>
11154    and <literal>array_to_json</> functions. However, the <literal>to_jsonb</>
11155    function supplies much the same functionality as these functions would.)
11156   </para>
11157
11158   <indexterm>
11159    <primary>to_json</primary>
11160   </indexterm>
11161   <indexterm>
11162    <primary>array_to_json</primary>
11163   </indexterm>
11164   <indexterm>
11165    <primary>row_to_json</primary>
11166   </indexterm>
11167   <indexterm>
11168    <primary>json_build_array</primary>
11169   </indexterm>
11170   <indexterm>
11171    <primary>json_build_object</primary>
11172   </indexterm>
11173   <indexterm>
11174    <primary>json_object</primary>
11175   </indexterm>
11176   <indexterm>
11177    <primary>to_jsonb</primary>
11178   </indexterm>
11179   <indexterm>
11180    <primary>jsonb_build_array</primary>
11181   </indexterm>
11182   <indexterm>
11183    <primary>jsonb_build_object</primary>
11184   </indexterm>
11185   <indexterm>
11186    <primary>jsonb_object</primary>
11187   </indexterm>
11188
11189   <table id="functions-json-creation-table">
11190     <title>JSON Creation Functions</title>
11191     <tgroup cols="4">
11192      <thead>
11193       <row>
11194        <entry>Function</entry>
11195        <entry>Description</entry>
11196        <entry>Example</entry>
11197        <entry>Example Result</entry>
11198       </row>
11199      </thead>
11200      <tbody>
11201       <row>
11202        <entry><para><literal>to_json(anyelement)</literal>
11203           </para><para><literal>to_jsonb(anyelement)</literal>
11204        </para></entry>
11205        <entry>
11206          Returns the value as <type>json</> or <type>jsonb</>.
11207          Arrays and composites are converted
11208          (recursively) to arrays and objects; otherwise, if there is a cast
11209          from the type to <type>json</type>, the cast function will be used to
11210          perform the conversion; otherwise, a scalar value is produced.
11211          For any scalar type other than a number, a Boolean, or a null value,
11212          the text representation will be used, in such a fashion that it is a
11213          valid <type>json</> or <type>jsonb</> value.
11214        </entry>
11215        <entry><literal>to_json('Fred said "Hi."'::text)</literal></entry>
11216        <entry><literal>"Fred said \"Hi.\""</literal></entry>
11217       </row>
11218       <row>
11219        <entry>
11220          <literal>array_to_json(anyarray [, pretty_bool])</literal>
11221        </entry>
11222        <entry>
11223          Returns the array as a JSON array. A PostgreSQL multidimensional array
11224          becomes a JSON array of arrays. Line feeds will be added between
11225          dimension-1 elements if <parameter>pretty_bool</parameter> is true.
11226        </entry>
11227        <entry><literal>array_to_json('{{1,5},{99,100}}'::int[])</literal></entry>
11228        <entry><literal>[[1,5],[99,100]]</literal></entry>
11229       </row>
11230       <row>
11231        <entry>
11232          <literal>row_to_json(record [, pretty_bool])</literal>
11233        </entry>
11234        <entry>
11235          Returns the row as a JSON object. Line feeds will be added between
11236          level-1 elements if <parameter>pretty_bool</parameter> is true.
11237        </entry>
11238        <entry><literal>row_to_json(row(1,'foo'))</literal></entry>
11239        <entry><literal>{"f1":1,"f2":"foo"}</literal></entry>
11240       </row>
11241       <row>
11242        <entry><para><literal>json_build_array(VARIADIC "any")</literal>
11243           </para><para><literal>jsonb_build_array(VARIADIC "any")</literal>
11244        </para></entry>
11245        <entry>
11246          Builds a possibly-heterogeneously-typed JSON array out of a variadic
11247          argument list.
11248        </entry>
11249        <entry><literal>json_build_array(1,2,'3',4,5)</literal></entry>
11250        <entry><literal>[1, 2, "3", 4, 5]</literal></entry>
11251       </row>
11252       <row>
11253        <entry><para><literal>json_build_object(VARIADIC "any")</literal>
11254           </para><para><literal>jsonb_build_object(VARIADIC "any")</literal>
11255        </para></entry>
11256        <entry>
11257          Builds a JSON object out of a variadic argument list.  By
11258          convention, the argument list consists of alternating
11259          keys and values.
11260        </entry>
11261        <entry><literal>json_build_object('foo',1,'bar',2)</literal></entry>
11262        <entry><literal>{"foo": 1, "bar": 2}</literal></entry>
11263       </row>
11264       <row>
11265        <entry><para><literal>json_object(text[])</literal>
11266           </para><para><literal>jsonb_object(text[])</literal>
11267        </para></entry>
11268        <entry>
11269          Builds a JSON object out of a text array.  The array must have either
11270          exactly one dimension with an even number of members, in which case
11271          they are taken as alternating key/value pairs, or two dimensions
11272          such that each inner array has exactly two elements, which
11273          are taken as a key/value pair.
11274        </entry>
11275        <entry><para><literal>json_object('{a, 1, b, "def", c, 3.5}')</></para>
11276         <para><literal>json_object('{{a, 1},{b, "def"},{c, 3.5}}')</></para></entry>
11277        <entry><literal>{"a": "1", "b": "def", "c": "3.5"}</literal></entry>
11278       </row>
11279       <row>
11280        <entry><para><literal>json_object(keys text[], values text[])</literal>
11281           </para><para><literal>jsonb_object(keys text[], values text[])</literal>
11282        </para></entry>
11283        <entry>
11284          This form of <function>json_object</> takes keys and values pairwise from two separate
11285          arrays. In all other respects it is identical to the one-argument form.
11286        </entry>
11287        <entry><literal>json_object('{a, b}', '{1,2}')</literal></entry>
11288        <entry><literal>{"a": "1", "b": "2"}</literal></entry>
11289       </row>
11290      </tbody>
11291     </tgroup>
11292    </table>
11293
11294   <note>
11295     <para>
11296      <function>array_to_json</> and <function>row_to_json</> have the same
11297      behavior as <function>to_json</> except for offering a pretty-printing
11298      option.  The behavior described for <function>to_json</> likewise applies
11299      to each individual value converted by the other JSON creation functions.
11300     </para>
11301   </note>
11302
11303   <note>
11304     <para>
11305      The <xref linkend="hstore"> extension has a cast
11306      from <type>hstore</type> to <type>json</type>, so that
11307      <type>hstore</type> values converted via the JSON creation functions
11308      will be represented as JSON objects, not as primitive string values.
11309     </para>
11310   </note>
11311
11312   <para>
11313    <xref linkend="functions-json-processing-table"> shows the functions that
11314    are available for processing <type>json</type> and <type>jsonb</type> values.
11315   </para>
11316
11317   <indexterm>
11318    <primary>json_array_length</primary>
11319   </indexterm>
11320   <indexterm>
11321    <primary>jsonb_array_length</primary>
11322   </indexterm>
11323   <indexterm>
11324    <primary>json_each</primary>
11325   </indexterm>
11326   <indexterm>
11327    <primary>jsonb_each</primary>
11328   </indexterm>
11329   <indexterm>
11330    <primary>json_each_text</primary>
11331   </indexterm>
11332   <indexterm>
11333    <primary>jsonb_each_text</primary>
11334   </indexterm>
11335   <indexterm>
11336    <primary>json_extract_path</primary>
11337   </indexterm>
11338   <indexterm>
11339    <primary>jsonb_extract_path</primary>
11340   </indexterm>
11341   <indexterm>
11342    <primary>json_extract_path_text</primary>
11343   </indexterm>
11344   <indexterm>
11345    <primary>jsonb_extract_path_text</primary>
11346   </indexterm>
11347   <indexterm>
11348    <primary>json_object_keys</primary>
11349   </indexterm>
11350   <indexterm>
11351    <primary>jsonb_object_keys</primary>
11352   </indexterm>
11353   <indexterm>
11354    <primary>json_populate_record</primary>
11355   </indexterm>
11356   <indexterm>
11357    <primary>jsonb_populate_record</primary>
11358   </indexterm>
11359   <indexterm>
11360    <primary>json_populate_recordset</primary>
11361   </indexterm>
11362   <indexterm>
11363    <primary>jsonb_populate_recordset</primary>
11364   </indexterm>
11365   <indexterm>
11366    <primary>json_array_elements</primary>
11367   </indexterm>
11368   <indexterm>
11369    <primary>jsonb_array_elements</primary>
11370   </indexterm>
11371   <indexterm>
11372    <primary>json_array_elements_text</primary>
11373   </indexterm>
11374   <indexterm>
11375    <primary>jsonb_array_elements_text</primary>
11376   </indexterm>
11377   <indexterm>
11378    <primary>json_typeof</primary>
11379   </indexterm>
11380   <indexterm>
11381    <primary>jsonb_typeof</primary>
11382   </indexterm>
11383   <indexterm>
11384    <primary>json_to_record</primary>
11385   </indexterm>
11386   <indexterm>
11387    <primary>jsonb_to_record</primary>
11388   </indexterm>
11389   <indexterm>
11390    <primary>json_to_recordset</primary>
11391   </indexterm>
11392   <indexterm>
11393    <primary>jsonb_to_recordset</primary>
11394   </indexterm>
11395   <indexterm>
11396    <primary>json_strip_nulls</primary>
11397   </indexterm>
11398   <indexterm>
11399    <primary>jsonb_strip_nulls</primary>
11400   </indexterm>
11401   <indexterm>
11402    <primary>jsonb_set</primary>
11403   </indexterm>
11404   <indexterm>
11405    <primary>jsonb_insert</primary>
11406   </indexterm>
11407   <indexterm>
11408    <primary>jsonb_pretty</primary>
11409   </indexterm>
11410
11411   <table id="functions-json-processing-table">
11412     <title>JSON Processing Functions</title>
11413     <tgroup cols="5">
11414      <thead>
11415       <row>
11416        <entry>Function</entry>
11417        <entry>Return Type</entry>
11418        <entry>Description</entry>
11419        <entry>Example</entry>
11420        <entry>Example Result</entry>
11421       </row>
11422      </thead>
11423      <tbody>
11424       <row>
11425        <entry><para><literal>json_array_length(json)</literal>
11426          </para><para><literal>jsonb_array_length(jsonb)</literal>
11427        </para></entry>
11428        <entry><type>int</type></entry>
11429        <entry>
11430          Returns the number of elements in the outermost JSON array.
11431        </entry>
11432        <entry><literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal></entry>
11433        <entry><literal>5</literal></entry>
11434       </row>
11435       <row>
11436        <entry><para><literal>json_each(json)</literal>
11437          </para><para><literal>jsonb_each(jsonb)</literal>
11438        </para></entry>
11439        <entry><para><literal>setof key text, value json</literal>
11440          </para><para><literal>setof key text, value jsonb</literal>
11441        </para></entry>
11442        <entry>
11443          Expands the outermost JSON object into a set of key/value pairs.
11444        </entry>
11445        <entry><literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal></entry>
11446        <entry>
11447 <programlisting>
11448  key | value
11449 -----+-------
11450  a   | "foo"
11451  b   | "bar"
11452 </programlisting>
11453        </entry>
11454       </row>
11455       <row>
11456        <entry><para><literal>json_each_text(json)</literal>
11457          </para><para><literal>jsonb_each_text(jsonb)</literal>
11458        </para></entry>
11459        <entry><type>setof key text, value text</type></entry>
11460        <entry>
11461          Expands the outermost JSON object into a set of key/value pairs. The
11462          returned values will be of type <type>text</>.
11463        </entry>
11464        <entry><literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal></entry>
11465        <entry>
11466 <programlisting>
11467  key | value
11468 -----+-------
11469  a   | foo
11470  b   | bar
11471 </programlisting>
11472        </entry>
11473       </row>
11474       <row>
11475        <entry><para><literal>json_extract_path(from_json json, VARIADIC path_elems text[])</literal>
11476         </para><para><literal>jsonb_extract_path(from_json jsonb, VARIADIC path_elems text[])</literal>
11477        </para></entry>
11478        <entry><para><type>json</type></para><para><type>jsonb</type>
11479        </para></entry>
11480        <entry>
11481          Returns JSON value pointed to by <replaceable>path_elems</replaceable>
11482          (equivalent to <literal>#&gt;</literal> operator).
11483        </entry>
11484        <entry><literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</literal></entry>
11485        <entry><literal>{"f5":99,"f6":"foo"}</literal></entry>
11486       </row>
11487       <row>
11488        <entry><para><literal>json_extract_path_text(from_json json, VARIADIC path_elems text[])</literal>
11489          </para><para><literal>jsonb_extract_path_text(from_json jsonb, VARIADIC path_elems text[])</literal>
11490        </para></entry>
11491        <entry><type>text</type></entry>
11492        <entry>
11493          Returns JSON value pointed to by <replaceable>path_elems</replaceable>
11494          as <type>text</>
11495          (equivalent to <literal>#&gt;&gt;</literal> operator).
11496        </entry>
11497        <entry><literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</literal></entry>
11498        <entry><literal>foo</literal></entry>
11499       </row>
11500       <row>
11501        <entry><para><literal>json_object_keys(json)</literal>
11502          </para><para><literal>jsonb_object_keys(jsonb)</literal>
11503        </para></entry>
11504        <entry><type>setof text</type></entry>
11505        <entry>
11506           Returns set of keys in the outermost JSON object.
11507        </entry>
11508        <entry><literal>json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal></entry>
11509        <entry>
11510 <programlisting>
11511  json_object_keys
11512 ------------------
11513  f1
11514  f2
11515 </programlisting>
11516        </entry>
11517       </row>
11518       <row>
11519        <entry><para><literal>json_populate_record(base anyelement, from_json json)</literal>
11520          </para><para><literal>jsonb_populate_record(base anyelement, from_json jsonb)</literal>
11521        </para></entry>
11522        <entry><type>anyelement</type></entry>
11523        <entry>
11524          Expands the object in <replaceable>from_json</replaceable> to a row
11525          whose columns match the record type defined by <replaceable>base</>
11526          (see note below).
11527        </entry>
11528        <entry><literal>select * from json_populate_record(null::myrowtype, '{"a":1,"b":2}')</literal></entry>
11529        <entry>
11530 <programlisting>
11531  a | b
11532 ---+---
11533  1 | 2
11534 </programlisting>
11535        </entry>
11536       </row>
11537       <row>
11538        <entry><para><literal>json_populate_recordset(base anyelement, from_json json)</literal>
11539          </para><para><literal>jsonb_populate_recordset(base anyelement, from_json jsonb)</literal>
11540        </para></entry>
11541        <entry><type>setof anyelement</type></entry>
11542        <entry>
11543          Expands the outermost array of objects
11544          in <replaceable>from_json</replaceable> to a set of rows whose
11545          columns match the record type defined by <replaceable>base</> (see
11546          note below).
11547        </entry>
11548        <entry><literal>select * from json_populate_recordset(null::myrowtype, '[{"a":1,"b":2},{"a":3,"b":4}]')</literal></entry>
11549        <entry>
11550 <programlisting>
11551  a | b
11552 ---+---
11553  1 | 2
11554  3 | 4
11555 </programlisting>
11556        </entry>
11557       </row>
11558       <row>
11559        <entry><para><literal>json_array_elements(json)</literal>
11560          </para><para><literal>jsonb_array_elements(jsonb)</literal>
11561        </para></entry>
11562        <entry><para><type>setof json</type>
11563          </para><para><type>setof jsonb</type>
11564        </para></entry>
11565        <entry>
11566          Expands a JSON array to a set of JSON values.
11567        </entry>
11568        <entry><literal>select * from json_array_elements('[1,true, [2,false]]')</literal></entry>
11569        <entry>
11570 <programlisting>
11571    value
11572 -----------
11573  1
11574  true
11575  [2,false]
11576 </programlisting>
11577        </entry>
11578       </row>
11579       <row>
11580        <entry><para><literal>json_array_elements_text(json)</literal>
11581          </para><para><literal>jsonb_array_elements_text(jsonb)</literal>
11582        </para></entry>
11583        <entry><type>setof text</type></entry>
11584        <entry>
11585          Expands a JSON array to a set of <type>text</> values.
11586        </entry>
11587        <entry><literal>select * from json_array_elements_text('["foo", "bar"]')</literal></entry>
11588        <entry>
11589 <programlisting>
11590    value
11591 -----------
11592  foo
11593  bar
11594 </programlisting>
11595        </entry>
11596       </row>
11597       <row>
11598        <entry><para><literal>json_typeof(json)</literal>
11599          </para><para><literal>jsonb_typeof(jsonb)</literal>
11600        </para></entry>
11601        <entry><type>text</type></entry>
11602        <entry>
11603          Returns the type of the outermost JSON value as a text string.
11604          Possible types are
11605          <literal>object</>, <literal>array</>, <literal>string</>, <literal>number</>,
11606          <literal>boolean</>, and <literal>null</>.
11607        </entry>
11608        <entry><literal>json_typeof('-123.4')</literal></entry>
11609        <entry><literal>number</literal></entry>
11610       </row>
11611       <row>
11612        <entry><para><literal>json_to_record(json)</literal>
11613           </para><para><literal>jsonb_to_record(jsonb)</literal>
11614        </para></entry>
11615        <entry><type>record</type></entry>
11616        <entry>
11617          Builds an arbitrary record from a JSON object (see note below).  As
11618          with all functions returning <type>record</>, the caller must
11619          explicitly define the structure of the record with an <literal>AS</>
11620          clause.
11621        </entry>
11622        <entry><literal>select * from json_to_record('{"a":1,"b":[1,2,3],"c":"bar"}') as x(a int, b text, d text) </literal></entry>
11623        <entry>
11624 <programlisting>
11625  a |    b    | d
11626 ---+---------+---
11627  1 | [1,2,3] |
11628 </programlisting>
11629        </entry>
11630       </row>
11631       <row>
11632        <entry><para><literal>json_to_recordset(json)</literal>
11633          </para><para><literal>jsonb_to_recordset(jsonb)</literal>
11634        </para></entry>
11635        <entry><type>setof record</type></entry>
11636        <entry>
11637          Builds an arbitrary set of records from a JSON array of objects (see
11638          note below).  As with all functions returning <type>record</>, the
11639          caller must explicitly define the structure of the record with
11640          an <literal>AS</> clause.
11641        </entry>
11642        <entry><literal>select * from json_to_recordset('[{"a":1,"b":"foo"},{"a":"2","c":"bar"}]') as x(a int, b text);</literal></entry>
11643        <entry>
11644 <programlisting>
11645  a |  b
11646 ---+-----
11647  1 | foo
11648  2 |
11649 </programlisting>
11650        </entry>
11651       </row>
11652       <row>
11653        <entry><para><literal>json_strip_nulls(from_json json)</literal>
11654          </para><para><literal>jsonb_strip_nulls(from_json jsonb)</literal>
11655        </para></entry>
11656        <entry><para><type>json</type></para><para><type>jsonb</type></para></entry>
11657        <entry>
11658          Returns <replaceable>from_json</replaceable>
11659          with all object fields that have null values omitted. Other null values
11660          are untouched.
11661        </entry>
11662        <entry><literal>json_strip_nulls('[{"f1":1,"f2":null},2,null,3]')</literal></entry>
11663        <entry><literal>[{"f1":1},2,null,3]</literal></entry>
11664        </row>
11665       <row>
11666        <entry><para><literal>jsonb_set(target jsonb, path text[], new_value jsonb<optional>, <parameter>create_missing</parameter> <type>boolean</type></optional>)</literal>
11667          </para></entry>
11668        <entry><para><type>jsonb</type></para></entry>
11669        <entry>
11670          Returns <replaceable>target</replaceable>
11671          with the section designated by <replaceable>path</replaceable>
11672          replaced by <replaceable>new_value</replaceable>, or with
11673          <replaceable>new_value</replaceable> added if
11674          <replaceable>create_missing</replaceable> is true ( default is
11675          <literal>true</>) and the item
11676          designated by <replaceable>path</replaceable> does not exist.
11677          As with the path orientated operators, negative integers that
11678          appear in <replaceable>path</replaceable> count from the end
11679          of JSON arrays.
11680        </entry>
11681        <entry><para><literal>jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}','[2,3,4]', false)</literal>
11682          </para><para><literal>jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}','[2,3,4]')</literal>
11683          </para></entry>
11684        <entry><para><literal>[{"f1":[2,3,4],"f2":null},2,null,3]</literal>
11685          </para><para><literal>[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</literal>
11686         </para></entry>
11687        </row>
11688       <row>
11689        <entry>
11690            <para><literal>
11691            jsonb_insert(target jsonb, path text[], new_value jsonb, <optional><parameter>insert_after</parameter> <type>boolean</type></optional>)
11692            </literal></para>
11693        </entry>
11694        <entry><para><type>jsonb</type></para></entry>
11695        <entry>
11696          Returns <replaceable>target</replaceable> with
11697          <replaceable>new_value</replaceable> inserted. If
11698          <replaceable>target</replaceable> section designated by
11699          <replaceable>path</replaceable> is in a JSONB array,
11700          <replaceable>new_value</replaceable> will be inserted before target or
11701          after if <replaceable>insert_after</replaceable> is true (default is
11702          <literal>false</>). If <replaceable>target</replaceable> section
11703          designated by <replaceable>path</replaceable> is in JSONB object,
11704          <replaceable>new_value</replaceable> will be inserted only if
11705          <replaceable>target</replaceable> does not exist. As with the path
11706          orientated operators, negative integers that appear in
11707          <replaceable>path</replaceable> count from the end of JSON arrays.
11708        </entry>
11709        <entry>
11710            <para><literal>
11711                jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')
11712            </literal></para>
11713            <para><literal>
11714                jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)
11715            </literal></para>
11716        </entry>
11717        <entry><para><literal>{"a": [0, "new_value", 1, 2]}</literal>
11718          </para><para><literal>{"a": [0, 1, "new_value", 2]}</literal>
11719         </para></entry>
11720        </row>
11721       <row>
11722        <entry><para><literal>jsonb_pretty(from_json jsonb)</literal>
11723          </para></entry>
11724        <entry><para><type>text</type></para></entry>
11725        <entry>
11726          Returns <replaceable>from_json</replaceable>
11727          as indented JSON text.
11728        </entry>
11729        <entry><literal>jsonb_pretty('[{"f1":1,"f2":null},2,null,3]')</literal></entry>
11730        <entry>
11731 <programlisting>
11732 [
11733     {
11734         "f1": 1,
11735         "f2": null
11736     },
11737     2,
11738     null,
11739     3
11740 ]
11741 </programlisting>
11742         </entry>
11743        </row>
11744      </tbody>
11745     </tgroup>
11746    </table>
11747
11748   <note>
11749     <para>
11750       Many of these functions and operators will convert Unicode escapes in
11751       JSON strings to the appropriate single character.  This is a non-issue
11752       if the input is type <type>jsonb</>, because the conversion was already
11753       done; but for <type>json</> input, this may result in throwing an error,
11754       as noted in <xref linkend="datatype-json">.
11755     </para>
11756   </note>
11757
11758   <note>
11759     <para>
11760       In <function>json_populate_record</>, <function>json_populate_recordset</>,
11761       <function>json_to_record</> and <function>json_to_recordset</>,
11762       type coercion from the JSON is <quote>best effort</> and may not result
11763       in desired values for some types.  JSON keys are matched to
11764       identical column names in the target row type.  JSON fields that do not
11765       appear in the target row type will be omitted from the output, and
11766       target columns that do not match any JSON field will simply be NULL.
11767     </para>
11768   </note>
11769
11770   <note>
11771     <para>
11772       All the items of the <literal>path</> parameter of <literal>jsonb_set</>
11773       as well as <literal>jsonb_insert</> except the last item must be present
11774       in the <literal>target</>. If <literal>create_missing</> is false, all
11775       items of the <literal>path</> parameter of <literal>jsonb_set</> must be
11776       present. If these conditions are not met the <literal>target</> is
11777       returned unchanged.
11778     </para>
11779     <para>
11780       If the last path item is an object key, it will be created if it
11781       is absent and given the new value. If the last path item is an array
11782       index, if it is positive the item to set is found by counting from
11783       the left, and if negative by counting from the right - <literal>-1</>
11784       designates the rightmost element, and so on.
11785       If the item is out of the range -array_length .. array_length -1,
11786       and create_missing is true, the new value is added at the beginning
11787       of the array if the item is negative, and at the end of the array if
11788       it is positive.
11789     </para>
11790   </note>
11791
11792   <note>
11793     <para>
11794       The <literal>json_typeof</> function's <literal>null</> return value
11795       should not be confused with a SQL NULL.  While
11796       calling <literal>json_typeof('null'::json)</> will
11797       return <literal>null</>, calling <literal>json_typeof(NULL::json)</>
11798       will return a SQL NULL.
11799     </para>
11800   </note>
11801
11802   <note>
11803     <para>
11804       If the argument to <literal>json_strip_nulls</> contains duplicate
11805       field names in any object, the result could be semantically somewhat
11806       different, depending on the order in which they occur. This is not an
11807       issue for <literal>jsonb_strip_nulls</> since <type>jsonb</type> values never have
11808       duplicate object field names.
11809     </para>
11810   </note>
11811
11812   <para>
11813     See also <xref linkend="functions-aggregate"> for the aggregate
11814     function <function>json_agg</function> which aggregates record
11815     values as JSON, and the aggregate function
11816     <function>json_object_agg</function> which aggregates pairs of values
11817     into a JSON object, and their <type>jsonb</type> equivalents,
11818     <function>jsonb_agg</> and <function>jsonb_object_agg</>.
11819   </para>
11820
11821  </sect1>
11822
11823  <sect1 id="functions-sequence">
11824   <title>Sequence Manipulation Functions</title>
11825
11826   <indexterm>
11827    <primary>sequence</primary>
11828   </indexterm>
11829   <indexterm>
11830    <primary>nextval</primary>
11831   </indexterm>
11832   <indexterm>
11833    <primary>currval</primary>
11834   </indexterm>
11835   <indexterm>
11836    <primary>lastval</primary>
11837   </indexterm>
11838   <indexterm>
11839    <primary>setval</primary>
11840   </indexterm>
11841
11842   <para>
11843    This section describes functions for operating on <firstterm>sequence
11844    objects</firstterm>, also called sequence generators or just sequences.
11845    Sequence objects are special single-row tables created with <xref
11846    linkend="sql-createsequence">.
11847    Sequence objects are commonly used to generate unique identifiers
11848    for rows of a table.  The sequence functions, listed in <xref
11849    linkend="functions-sequence-table">, provide simple, multiuser-safe
11850    methods for obtaining successive sequence values from sequence
11851    objects.
11852   </para>
11853
11854    <table id="functions-sequence-table">
11855     <title>Sequence Functions</title>
11856     <tgroup cols="3">
11857      <thead>
11858       <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11859      </thead>
11860
11861      <tbody>
11862       <row>
11863         <entry><literal><function>currval(<type>regclass</type>)</function></literal></entry>
11864         <entry><type>bigint</type></entry>
11865         <entry>Return value most recently obtained with
11866         <function>nextval</function> for specified sequence</entry>
11867       </row>
11868       <row>
11869         <entry><literal><function>lastval()</function></literal></entry>
11870         <entry><type>bigint</type></entry>
11871         <entry>Return value most recently obtained with
11872         <function>nextval</function> for any sequence</entry>
11873       </row>
11874       <row>
11875         <entry><literal><function>nextval(<type>regclass</type>)</function></literal></entry>
11876         <entry><type>bigint</type></entry>
11877         <entry>Advance sequence and return new value</entry>
11878       </row>
11879       <row>
11880         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>)</function></literal></entry>
11881         <entry><type>bigint</type></entry>
11882         <entry>Set sequence's current value</entry>
11883       </row>
11884       <row>
11885         <entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</function></literal></entry>
11886         <entry><type>bigint</type></entry>
11887         <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
11888       </row>
11889      </tbody>
11890     </tgroup>
11891    </table>
11892
11893   <para>
11894    The sequence to be operated on by a sequence function is specified by
11895    a <type>regclass</> argument, which is simply the OID of the sequence in the
11896    <structname>pg_class</> system catalog.  You do not have to look up the
11897    OID by hand, however, since the <type>regclass</> data type's input
11898    converter will do the work for you.  Just write the sequence name enclosed
11899    in single quotes so that it looks like a literal constant.  For
11900    compatibility with the handling of ordinary
11901    <acronym>SQL</acronym> names, the string will be converted to lower case
11902    unless it contains double quotes around the sequence name.  Thus:
11903 <programlisting>
11904 nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
11905 nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
11906 nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
11907 </programlisting>
11908    The sequence name can be schema-qualified if necessary:
11909 <programlisting>
11910 nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
11911 nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
11912 nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
11913 </programlisting>
11914    See <xref linkend="datatype-oid"> for more information about
11915    <type>regclass</>.
11916   </para>
11917
11918   <note>
11919    <para>
11920     Before <productname>PostgreSQL</productname> 8.1, the arguments of the
11921     sequence functions were of type <type>text</>, not <type>regclass</>, and
11922     the above-described conversion from a text string to an OID value would
11923     happen at run time during each call.  For backward compatibility, this
11924     facility still exists, but internally it is now handled as an implicit
11925     coercion from <type>text</> to <type>regclass</> before the function is
11926     invoked.
11927    </para>
11928
11929    <para>
11930     When you write the argument of a sequence function as an unadorned
11931     literal string, it becomes a constant of type <type>regclass</>.
11932     Since this is really just an OID, it will track the originally
11933     identified sequence despite later renaming, schema reassignment,
11934     etc.  This <quote>early binding</> behavior is usually desirable for
11935     sequence references in column defaults and views.  But sometimes you might
11936     want <quote>late binding</> where the sequence reference is resolved
11937     at run time.  To get late-binding behavior, force the constant to be
11938     stored as a <type>text</> constant instead of <type>regclass</>:
11939 <programlisting>
11940 nextval('foo'::text)      <lineannotation><literal>foo</literal> is looked up at runtime</>
11941 </programlisting>
11942     Note that late binding was the only behavior supported in
11943     <productname>PostgreSQL</productname> releases before 8.1, so you
11944     might need to do this to preserve the semantics of old applications.
11945    </para>
11946
11947    <para>
11948     Of course, the argument of a sequence function can be an expression
11949     as well as a constant.  If it is a text expression then the implicit
11950     coercion will result in a run-time lookup.
11951    </para>
11952   </note>
11953
11954   <para>
11955    The available sequence functions are:
11956
11957     <variablelist>
11958      <varlistentry>
11959       <term><function>nextval</function></term>
11960       <listitem>
11961        <para>
11962         Advance the sequence object to its next value and return that
11963         value.  This is done atomically: even if multiple sessions
11964         execute <function>nextval</function> concurrently, each will safely receive
11965         a distinct sequence value.
11966        </para>
11967
11968        <para>
11969         If a sequence object has been created with default parameters,
11970         successive <function>nextval</function> calls will return successive
11971         values beginning with 1.  Other behaviors can be obtained by using
11972         special parameters in the <xref linkend="sql-createsequence"> command;
11973         see its command reference page for more information.
11974        </para>
11975
11976        <important>
11977         <para>
11978          To avoid blocking concurrent transactions that obtain numbers from
11979          the same sequence, a <function>nextval</function> operation is never
11980          rolled back; that is, once a value has been fetched it is considered
11981          used and will not be returned again.  This is true even if the
11982          surrounding transaction later aborts, or if the calling query ends
11983          up not using the value.  For example an <command>INSERT</> with
11984          an <literal>ON CONFLICT</> clause will compute the to-be-inserted
11985          tuple, including doing any required <function>nextval</function>
11986          calls, before detecting any conflict that would cause it to follow
11987          the <literal>ON CONFLICT</> rule instead.  Such cases will leave
11988          unused <quote>holes</quote> in the sequence of assigned values.
11989          Thus, <productname>PostgreSQL</> sequence objects <emphasis>cannot
11990          be used to obtain <quote>gapless</> sequences</emphasis>.
11991         </para>
11992        </important>
11993
11994        <para>
11995         This function requires <literal>USAGE</literal>
11996         or <literal>UPDATE</literal> privilege on the sequence.
11997        </para>
11998       </listitem>
11999      </varlistentry>
12000
12001      <varlistentry>
12002       <term><function>currval</function></term>
12003       <listitem>
12004        <para>
12005         Return the value most recently obtained by <function>nextval</function>
12006         for this sequence in the current session.  (An error is
12007         reported if <function>nextval</function> has never been called for this
12008         sequence in this session.)  Because this is returning
12009         a session-local value, it gives a predictable answer whether or not
12010         other sessions have executed <function>nextval</function> since the
12011         current session did.
12012        </para>
12013
12014        <para>
12015         This function requires <literal>USAGE</literal>
12016         or <literal>SELECT</literal> privilege on the sequence.
12017        </para>
12018       </listitem>
12019      </varlistentry>
12020
12021      <varlistentry>
12022       <term><function>lastval</function></term>
12023       <listitem>
12024        <para>
12025         Return the value most recently returned by
12026         <function>nextval</> in the current session. This function is
12027         identical to <function>currval</function>, except that instead
12028         of taking the sequence name as an argument it refers to whichever
12029         sequence <function>nextval</function> was most recently applied to
12030         in the current session. It is an error to call
12031         <function>lastval</function> if <function>nextval</function>
12032         has not yet been called in the current session.
12033        </para>
12034
12035        <para>
12036         This function requires <literal>USAGE</literal>
12037         or <literal>SELECT</literal> privilege on the last used sequence.
12038        </para>
12039       </listitem>
12040      </varlistentry>
12041
12042      <varlistentry>
12043       <term><function>setval</function></term>
12044       <listitem>
12045        <para>
12046         Reset the sequence object's counter value.  The two-parameter
12047         form sets the sequence's <literal>last_value</literal> field to the
12048         specified value and sets its <literal>is_called</literal> field to
12049         <literal>true</literal>, meaning that the next
12050         <function>nextval</function> will advance the sequence before
12051         returning a value.  The value reported by <function>currval</> is
12052         also set to the specified value.  In the three-parameter form,
12053         <literal>is_called</literal> can be set to either <literal>true</literal>
12054         or <literal>false</literal>.  <literal>true</> has the same effect as
12055         the two-parameter form. If it is set to <literal>false</literal>, the
12056         next <function>nextval</function> will return exactly the specified
12057         value, and sequence advancement commences with the following
12058         <function>nextval</function>.  Furthermore, the value reported by
12059         <function>currval</> is not changed in this case.  For example,
12060
12061 <screen>
12062 SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
12063 SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
12064 SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
12065 </screen>
12066
12067         The result returned by <function>setval</function> is just the value of its
12068         second argument.
12069        </para>
12070        <important>
12071         <para>
12072          Because sequences are non-transactional, changes made by
12073          <function>setval</function> are not undone if the transaction rolls
12074          back.
12075         </para>
12076        </important>
12077
12078        <para>
12079         This function requires <literal>UPDATE</literal> privilege on the
12080         sequence.
12081        </para>
12082       </listitem>
12083      </varlistentry>
12084     </variablelist>
12085   </para>
12086
12087  </sect1>
12088
12089
12090  <sect1 id="functions-conditional">
12091   <title>Conditional Expressions</title>
12092
12093   <indexterm>
12094    <primary>CASE</primary>
12095   </indexterm>
12096
12097   <indexterm>
12098    <primary>conditional expression</primary>
12099   </indexterm>
12100
12101   <para>
12102    This section describes the <acronym>SQL</acronym>-compliant conditional expressions
12103    available in <productname>PostgreSQL</productname>.
12104   </para>
12105
12106   <tip>
12107    <para>
12108     If your needs go beyond the capabilities of these conditional
12109     expressions, you might want to consider writing a stored procedure
12110     in a more expressive programming language.
12111    </para>
12112   </tip>
12113
12114   <sect2 id="functions-case">
12115    <title><literal>CASE</></title>
12116
12117   <para>
12118    The <acronym>SQL</acronym> <token>CASE</token> expression is a
12119    generic conditional expression, similar to if/else statements in
12120    other programming languages:
12121
12122 <synopsis>
12123 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
12124      <optional>WHEN ...</optional>
12125      <optional>ELSE <replaceable>result</replaceable></optional>
12126 END
12127 </synopsis>
12128
12129    <token>CASE</token> clauses can be used wherever
12130    an expression is valid.  Each <replaceable>condition</replaceable> is an
12131    expression that returns a <type>boolean</type> result.  If the condition's
12132    result is true, the value of the <token>CASE</token> expression is the
12133    <replaceable>result</replaceable> that follows the condition, and the
12134    remainder of the <token>CASE</token> expression is not processed.  If the
12135    condition's result is not true, any subsequent <token>WHEN</token> clauses
12136    are examined in the same manner.  If no <token>WHEN</token>
12137    <replaceable>condition</replaceable> yields true, the value of the
12138    <token>CASE</> expression is the <replaceable>result</replaceable> of the
12139    <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
12140    omitted and no condition is true, the result is null.
12141   </para>
12142
12143    <para>
12144     An example:
12145 <screen>
12146 SELECT * FROM test;
12147
12148  a
12149 ---
12150  1
12151  2
12152  3
12153
12154
12155 SELECT a,
12156        CASE WHEN a=1 THEN 'one'
12157             WHEN a=2 THEN 'two'
12158             ELSE 'other'
12159        END
12160     FROM test;
12161
12162  a | case
12163 ---+-------
12164  1 | one
12165  2 | two
12166  3 | other
12167 </screen>
12168    </para>
12169
12170   <para>
12171    The data types of all the <replaceable>result</replaceable>
12172    expressions must be convertible to a single output type.
12173    See <xref linkend="typeconv-union-case"> for more details.
12174   </para>
12175
12176   <para>
12177    There is a <quote>simple</> form of <token>CASE</token> expression
12178    that is a variant of the general form above:
12179
12180 <synopsis>
12181 CASE <replaceable>expression</replaceable>
12182     WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
12183     <optional>WHEN ...</optional>
12184     <optional>ELSE <replaceable>result</replaceable></optional>
12185 END
12186 </synopsis>
12187
12188    The first
12189    <replaceable>expression</replaceable> is computed, then compared to
12190    each of the <replaceable>value</replaceable> expressions in the
12191    <token>WHEN</token> clauses until one is found that is equal to it.  If
12192    no match is found, the <replaceable>result</replaceable> of the
12193    <token>ELSE</token> clause (or a null value) is returned.  This is similar
12194    to the <function>switch</function> statement in C.
12195   </para>
12196
12197    <para>
12198     The example above can be written using the simple
12199     <token>CASE</token> syntax:
12200 <screen>
12201 SELECT a,
12202        CASE a WHEN 1 THEN 'one'
12203               WHEN 2 THEN 'two'
12204               ELSE 'other'
12205        END
12206     FROM test;
12207
12208  a | case
12209 ---+-------
12210  1 | one
12211  2 | two
12212  3 | other
12213 </screen>
12214    </para>
12215
12216    <para>
12217     A <token>CASE</token> expression does not evaluate any subexpressions
12218     that are not needed to determine the result.  For example, this is a
12219     possible way of avoiding a division-by-zero failure:
12220 <programlisting>
12221 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
12222 </programlisting>
12223    </para>
12224
12225    <note>
12226     <para>
12227      As described in <xref linkend="syntax-express-eval">, there are various
12228      situations in which subexpressions of an expression are evaluated at
12229      different times, so that the principle that <quote><token>CASE</token>
12230      evaluates only necessary subexpressions</quote> is not ironclad.  For
12231      example a constant <literal>1/0</> subexpression will usually result in
12232      a division-by-zero failure at planning time, even if it's within
12233      a <token>CASE</token> arm that would never be entered at run time.
12234     </para>
12235    </note>
12236   </sect2>
12237
12238   <sect2 id="functions-coalesce-nvl-ifnull">
12239    <title><literal>COALESCE</></title>
12240
12241   <indexterm>
12242    <primary>COALESCE</primary>
12243   </indexterm>
12244
12245   <indexterm>
12246    <primary>NVL</primary>
12247   </indexterm>
12248
12249   <indexterm>
12250    <primary>IFNULL</primary>
12251   </indexterm>
12252
12253 <synopsis>
12254 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
12255 </synopsis>
12256
12257   <para>
12258    The <function>COALESCE</function> function returns the first of its
12259    arguments that is not null.  Null is returned only if all arguments
12260    are null.  It is often used to substitute a default value for
12261    null values when data is retrieved for display, for example:
12262 <programlisting>
12263 SELECT COALESCE(description, short_description, '(none)') ...
12264 </programlisting>
12265    This returns <varname>description</> if it is not null, otherwise
12266    <varname>short_description</> if it is not null, otherwise <literal>(none)</>.
12267   </para>
12268
12269    <para>
12270     Like a <token>CASE</token> expression, <function>COALESCE</function> only
12271     evaluates the arguments that are needed to determine the result;
12272     that is, arguments to the right of the first non-null argument are
12273     not evaluated.  This SQL-standard function provides capabilities similar
12274     to <function>NVL</> and <function>IFNULL</>, which are used in some other
12275     database systems.
12276    </para>
12277   </sect2>
12278
12279   <sect2 id="functions-nullif">
12280    <title><literal>NULLIF</></title>
12281
12282   <indexterm>
12283    <primary>NULLIF</primary>
12284   </indexterm>
12285
12286 <synopsis>
12287 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
12288 </synopsis>
12289
12290   <para>
12291    The <function>NULLIF</function> function returns a null value if
12292    <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
12293    otherwise it returns <replaceable>value1</replaceable>.
12294    This can be used to perform the inverse operation of the
12295    <function>COALESCE</function> example given above:
12296 <programlisting>
12297 SELECT NULLIF(value, '(none)') ...
12298 </programlisting>
12299   </para>
12300   <para>
12301    In this example, if <literal>value</literal> is <literal>(none)</>,
12302    null is returned, otherwise the value of <literal>value</literal>
12303    is returned.
12304   </para>
12305
12306   </sect2>
12307
12308   <sect2 id="functions-greatest-least">
12309    <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
12310
12311   <indexterm>
12312    <primary>GREATEST</primary>
12313   </indexterm>
12314   <indexterm>
12315    <primary>LEAST</primary>
12316   </indexterm>
12317
12318 <synopsis>
12319 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
12320 </synopsis>
12321 <synopsis>
12322 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
12323 </synopsis>
12324
12325    <para>
12326     The <function>GREATEST</> and <function>LEAST</> functions select the
12327     largest or smallest value from a list of any number of expressions.
12328     The expressions must all be convertible to a common data type, which
12329     will be the type of the result
12330     (see <xref linkend="typeconv-union-case"> for details).  NULL values
12331     in the list are ignored.  The result will be NULL only if all the
12332     expressions evaluate to NULL.
12333    </para>
12334
12335    <para>
12336     Note that <function>GREATEST</> and <function>LEAST</> are not in
12337     the SQL standard, but are a common extension.  Some other databases
12338     make them return NULL if any argument is NULL, rather than only when
12339     all are NULL.
12340    </para>
12341   </sect2>
12342  </sect1>
12343
12344  <sect1 id="functions-array">
12345   <title>Array Functions and Operators</title>
12346
12347   <para>
12348    <xref linkend="array-operators-table"> shows the operators
12349    available for array types.
12350   </para>
12351
12352     <table id="array-operators-table">
12353      <title>Array Operators</title>
12354      <tgroup cols="4">
12355       <thead>
12356        <row>
12357         <entry>Operator</entry>
12358         <entry>Description</entry>
12359         <entry>Example</entry>
12360         <entry>Result</entry>
12361        </row>
12362       </thead>
12363       <tbody>
12364        <row>
12365         <entry> <literal>=</literal> </entry>
12366         <entry>equal</entry>
12367         <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
12368         <entry><literal>t</literal></entry>
12369        </row>
12370
12371        <row>
12372         <entry> <literal>&lt;&gt;</literal> </entry>
12373         <entry>not equal</entry>
12374         <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
12375         <entry><literal>t</literal></entry>
12376        </row>
12377
12378        <row>
12379         <entry> <literal>&lt;</literal> </entry>
12380         <entry>less than</entry>
12381         <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
12382         <entry><literal>t</literal></entry>
12383        </row>
12384
12385        <row>
12386         <entry> <literal>&gt;</literal> </entry>
12387         <entry>greater than</entry>
12388         <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
12389         <entry><literal>t</literal></entry>
12390        </row>
12391
12392        <row>
12393         <entry> <literal>&lt;=</literal> </entry>
12394         <entry>less than or equal</entry>
12395         <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
12396         <entry><literal>t</literal></entry>
12397        </row>
12398
12399        <row>
12400         <entry> <literal>&gt;=</literal> </entry>
12401         <entry>greater than or equal</entry>
12402         <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
12403         <entry><literal>t</literal></entry>
12404        </row>
12405
12406        <row>
12407         <entry> <literal>@&gt;</literal> </entry>
12408         <entry>contains</entry>
12409         <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
12410         <entry><literal>t</literal></entry>
12411        </row>
12412
12413        <row>
12414         <entry> <literal>&lt;@</literal> </entry>
12415         <entry>is contained by</entry>
12416         <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
12417         <entry><literal>t</literal></entry>
12418        </row>
12419
12420        <row>
12421         <entry> <literal>&amp;&amp;</literal> </entry>
12422         <entry>overlap (have elements in common)</entry>
12423         <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
12424         <entry><literal>t</literal></entry>
12425        </row>
12426
12427        <row>
12428         <entry> <literal>||</literal> </entry>
12429         <entry>array-to-array concatenation</entry>
12430         <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
12431         <entry><literal>{1,2,3,4,5,6}</literal></entry>
12432        </row>
12433
12434        <row>
12435         <entry> <literal>||</literal> </entry>
12436         <entry>array-to-array concatenation</entry>
12437         <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
12438         <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
12439        </row>
12440
12441        <row>
12442         <entry> <literal>||</literal> </entry>
12443         <entry>element-to-array concatenation</entry>
12444         <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
12445         <entry><literal>{3,4,5,6}</literal></entry>
12446        </row>
12447
12448        <row>
12449         <entry> <literal>||</literal> </entry>
12450         <entry>array-to-element concatenation</entry>
12451         <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
12452         <entry><literal>{4,5,6,7}</literal></entry>
12453        </row>
12454       </tbody>
12455      </tgroup>
12456     </table>
12457
12458   <para>
12459    Array comparisons compare the array contents element-by-element,
12460    using the default B-tree comparison function for the element data type.
12461    In multidimensional arrays the elements are visited in row-major order
12462    (last subscript varies most rapidly).
12463    If the contents of two arrays are equal but the dimensionality is
12464    different, the first difference in the dimensionality information
12465    determines the sort order.  (This is a change from versions of
12466    <productname>PostgreSQL</> prior to 8.2: older versions would claim
12467    that two arrays with the same contents were equal, even if the
12468    number of dimensions or subscript ranges were different.)
12469   </para>
12470
12471   <para>
12472    See <xref linkend="arrays"> for more details about array operator
12473    behavior.  See <xref linkend="indexes-types"> for more details about
12474    which operators support indexed operations.
12475   </para>
12476
12477   <para>
12478    <xref linkend="array-functions-table"> shows the functions
12479    available for use with array types. See <xref linkend="arrays">
12480    for more information  and examples of the use of these functions.
12481   </para>
12482
12483   <indexterm>
12484     <primary>array_append</primary>
12485   </indexterm>
12486   <indexterm>
12487     <primary>array_cat</primary>
12488   </indexterm>
12489   <indexterm>
12490     <primary>array_ndims</primary>
12491   </indexterm>
12492   <indexterm>
12493     <primary>array_dims</primary>
12494   </indexterm>
12495   <indexterm>
12496     <primary>array_fill</primary>
12497   </indexterm>
12498   <indexterm>
12499     <primary>array_length</primary>
12500   </indexterm>
12501   <indexterm>
12502     <primary>array_lower</primary>
12503   </indexterm>
12504   <indexterm>
12505     <primary>array_position</primary>
12506   </indexterm>
12507   <indexterm>
12508     <primary>array_positions</primary>
12509   </indexterm>
12510   <indexterm>
12511     <primary>array_prepend</primary>
12512   </indexterm>
12513   <indexterm>
12514     <primary>array_remove</primary>
12515   </indexterm>
12516   <indexterm>
12517     <primary>array_replace</primary>
12518   </indexterm>
12519   <indexterm>
12520     <primary>array_to_string</primary>
12521   </indexterm>
12522  <indexterm>
12523     <primary>array_upper</primary>
12524   </indexterm>
12525   <indexterm>
12526     <primary>cardinality</primary>
12527   </indexterm>
12528   <indexterm>
12529     <primary>string_to_array</primary>
12530   </indexterm>
12531   <indexterm>
12532     <primary>unnest</primary>
12533   </indexterm>
12534
12535     <table id="array-functions-table">
12536      <title>Array Functions</title>
12537      <tgroup cols="5">
12538       <thead>
12539        <row>
12540         <entry>Function</entry>
12541         <entry>Return Type</entry>
12542         <entry>Description</entry>
12543         <entry>Example</entry>
12544         <entry>Result</entry>
12545        </row>
12546       </thead>
12547       <tbody>
12548        <row>
12549         <entry>
12550          <literal>
12551           <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
12552          </literal>
12553         </entry>
12554         <entry><type>anyarray</type></entry>
12555         <entry>append an element to the end of an array</entry>
12556         <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
12557         <entry><literal>{1,2,3}</literal></entry>
12558        </row>
12559        <row>
12560         <entry>
12561          <literal>
12562           <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
12563          </literal>
12564         </entry>
12565         <entry><type>anyarray</type></entry>
12566         <entry>concatenate two arrays</entry>
12567         <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
12568         <entry><literal>{1,2,3,4,5}</literal></entry>
12569        </row>
12570        <row>
12571         <entry>
12572          <literal>
12573           <function>array_ndims</function>(<type>anyarray</type>)
12574          </literal>
12575         </entry>
12576         <entry><type>int</type></entry>
12577         <entry>returns the number of dimensions of the array</entry>
12578         <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
12579         <entry><literal>2</literal></entry>
12580        </row>
12581        <row>
12582         <entry>
12583          <literal>
12584           <function>array_dims</function>(<type>anyarray</type>)
12585          </literal>
12586         </entry>
12587         <entry><type>text</type></entry>
12588         <entry>returns a text representation of array's dimensions</entry>
12589         <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
12590         <entry><literal>[1:2][1:3]</literal></entry>
12591        </row>
12592        <row>
12593         <entry>
12594          <literal>
12595           <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
12596           <optional>, <type>int[]</type></optional>)
12597          </literal>
12598         </entry>
12599         <entry><type>anyarray</type></entry>
12600         <entry>returns an array initialized with supplied value and
12601          dimensions, optionally with lower bounds other than 1</entry>
12602         <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
12603         <entry><literal>[2:4]={7,7,7}</literal></entry>
12604        </row>
12605        <row>
12606         <entry>
12607          <literal>
12608           <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
12609          </literal>
12610         </entry>
12611         <entry><type>int</type></entry>
12612         <entry>returns the length of the requested array dimension</entry>
12613         <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
12614         <entry><literal>3</literal></entry>
12615        </row>
12616        <row>
12617         <entry>
12618          <literal>
12619           <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
12620          </literal>
12621         </entry>
12622         <entry><type>int</type></entry>
12623         <entry>returns lower bound of the requested array dimension</entry>
12624         <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
12625         <entry><literal>0</literal></entry>
12626        </row>
12627        <row>
12628         <entry>
12629          <literal>
12630           <function>array_position</function>(<type>anyarray</type>, <type>anyelement</type> <optional>, <type>int</type></optional>)
12631          </literal>
12632         </entry>
12633         <entry><type>int</type></entry>
12634         <entry>returns the subscript of the first occurrence of the second
12635         argument in the array, starting at the element indicated by the third
12636         argument or at the first element (array must be one-dimensional)</entry>
12637         <entry><literal>array_position(ARRAY['sun','mon','tue','wed','thu','fri','sat'], 'mon')</literal></entry>
12638         <entry><literal>2</literal></entry>
12639        </row>
12640        <row>
12641         <entry>
12642          <literal>
12643           <function>array_positions</function>(<type>anyarray</type>, <type>anyelement</type>)
12644          </literal>
12645         </entry>
12646         <entry><type>int[]</type></entry>
12647         <entry>returns an array of subscripts of all occurrences of the second
12648         argument in the array given as first argument (array must be
12649         one-dimensional)</entry>
12650         <entry><literal>array_positions(ARRAY['A','A','B','A'], 'A')</literal></entry>
12651         <entry><literal>{1,2,4}</literal></entry>
12652        </row>
12653        <row>
12654         <entry>
12655          <literal>
12656           <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
12657          </literal>
12658         </entry>
12659         <entry><type>anyarray</type></entry>
12660         <entry>append an element to the beginning of an array</entry>
12661         <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
12662         <entry><literal>{1,2,3}</literal></entry>
12663        </row>
12664        <row>
12665         <entry>
12666          <literal>
12667           <function>array_remove</function>(<type>anyarray</type>, <type>anyelement</type>)
12668          </literal>
12669         </entry>
12670         <entry><type>anyarray</type></entry>
12671         <entry>remove all elements equal to the given value from the array
12672          (array must be one-dimensional)</entry>
12673         <entry><literal>array_remove(ARRAY[1,2,3,2], 2)</literal></entry>
12674         <entry><literal>{1,3}</literal></entry>
12675        </row>
12676        <row>
12677         <entry>
12678          <literal>
12679           <function>array_replace</function>(<type>anyarray</type>, <type>anyelement</type>, <type>anyelement</type>)
12680          </literal>
12681         </entry>
12682         <entry><type>anyarray</type></entry>
12683         <entry>replace each array element equal to the given value with a new value</entry>
12684         <entry><literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal></entry>
12685         <entry><literal>{1,2,3,4}</literal></entry>
12686        </row>
12687        <row>
12688         <entry>
12689          <literal>
12690           <function>array_to_string</function>(<type>anyarray</type>, <type>text</type> <optional>, <type>text</type></optional>)
12691          </literal>
12692         </entry>
12693         <entry><type>text</type></entry>
12694         <entry>concatenates array elements using supplied delimiter and
12695          optional null string</entry>
12696         <entry><literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal></entry>
12697         <entry><literal>1,2,3,*,5</literal></entry>
12698        </row>
12699        <row>
12700         <entry>
12701          <literal>
12702           <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
12703          </literal>
12704         </entry>
12705         <entry><type>int</type></entry>
12706         <entry>returns upper bound of the requested array dimension</entry>
12707         <entry><literal>array_upper(ARRAY[1,8,3,7], 1)</literal></entry>
12708         <entry><literal>4</literal></entry>
12709        </row>
12710        <row>
12711         <entry>
12712          <literal>
12713           <function>cardinality</function>(<type>anyarray</type>)
12714          </literal>
12715         </entry>
12716         <entry><type>int</type></entry>
12717         <entry>returns the total number of elements in the array, or 0 if the array is empty</entry>
12718         <entry><literal>cardinality(ARRAY[[1,2],[3,4]])</literal></entry>
12719         <entry><literal>4</literal></entry>
12720        </row>
12721        <row>
12722         <entry>
12723          <literal>
12724           <function>string_to_array</function>(<type>text</type>, <type>text</type> <optional>, <type>text</type></optional>)
12725          </literal>
12726         </entry>
12727         <entry><type>text[]</type></entry>
12728         <entry>splits string into array elements using supplied delimiter and
12729          optional null string</entry>
12730         <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~', 'yy')</literal></entry>
12731         <entry><literal>{xx,NULL,zz}</literal></entry>
12732        </row>
12733        <row>
12734         <entry>
12735          <literal>
12736           <function>unnest</function>(<type>anyarray</type>)
12737          </literal>
12738         </entry>
12739         <entry><type>setof anyelement</type></entry>
12740         <entry>expand an array to a set of rows</entry>
12741         <entry><literal>unnest(ARRAY[1,2])</literal></entry>
12742         <entry><literallayout class="monospaced">1
12743 2</literallayout>(2 rows)</entry>
12744        </row>
12745        <row>
12746         <entry>
12747          <literal>
12748           <function>unnest</function>(<type>anyarray</type>, <type>anyarray</type> [, ...])
12749          </literal>
12750         </entry>
12751         <entry><type>setof anyelement, anyelement [, ...]</type></entry>
12752         <entry>expand multiple arrays (possibly of different types) to a set
12753          of rows.  This is only allowed in the FROM clause; see
12754          <xref linkend="queries-tablefunctions"></entry>
12755         <entry><literal>unnest(ARRAY[1,2],ARRAY['foo','bar','baz'])</literal></entry>
12756         <entry><literallayout class="monospaced">1    foo
12757 2    bar
12758 NULL baz</literallayout>(3 rows)</entry>
12759        </row>
12760       </tbody>
12761      </tgroup>
12762     </table>
12763
12764    <para>
12765     In <function>array_position</function> and <function>array_positions</>,
12766     each array element is compared to the searched value using
12767     <literal>IS NOT DISTINCT FROM</literal> semantics.
12768    </para>
12769
12770    <para>
12771     In <function>array_position</function>, <literal>NULL</literal> is returned
12772     if the value is not found.
12773    </para>
12774
12775    <para>
12776     In <function>array_positions</function>, <literal>NULL</literal> is returned
12777     only if the array is <literal>NULL</literal>; if the value is not found in
12778     the array, an empty array is returned instead.
12779    </para>
12780
12781    <para>
12782     In <function>string_to_array</function>, if the delimiter parameter is
12783     NULL, each character in the input string will become a separate element in
12784     the resulting array.  If the delimiter is an empty string, then the entire
12785     input string is returned as a one-element array.  Otherwise the input
12786     string is split at each occurrence of the delimiter string.
12787    </para>
12788
12789    <para>
12790     In <function>string_to_array</function>, if the null-string parameter
12791     is omitted or NULL, none of the substrings of the input will be replaced
12792     by NULL.
12793     In <function>array_to_string</function>, if the null-string parameter
12794     is omitted or NULL, any null elements in the array are simply skipped
12795     and not represented in the output string.
12796    </para>
12797
12798    <note>
12799     <para>
12800      There are two differences in the behavior of <function>string_to_array</>
12801      from pre-9.1 versions of <productname>PostgreSQL</>.
12802      First, it will return an empty (zero-element) array rather than NULL when
12803      the input string is of zero length.  Second, if the delimiter string is
12804      NULL, the function splits the input into individual characters, rather
12805      than returning NULL as before.
12806     </para>
12807    </note>
12808
12809    <para>
12810     See also <xref linkend="functions-aggregate"> about the aggregate
12811     function <function>array_agg</function> for use with arrays.
12812    </para>
12813   </sect1>
12814
12815  <sect1 id="functions-range">
12816   <title>Range Functions and Operators</title>
12817
12818   <para>
12819    See <xref linkend="rangetypes"> for an overview of range types.
12820   </para>
12821
12822   <para>
12823    <xref linkend="range-operators-table"> shows the operators
12824    available for range types.
12825   </para>
12826
12827     <table id="range-operators-table">
12828      <title>Range Operators</title>
12829      <tgroup cols="4">
12830       <thead>
12831        <row>
12832         <entry>Operator</entry>
12833         <entry>Description</entry>
12834         <entry>Example</entry>
12835         <entry>Result</entry>
12836        </row>
12837       </thead>
12838       <tbody>
12839        <row>
12840         <entry> <literal>=</literal> </entry>
12841         <entry>equal</entry>
12842         <entry><literal>int4range(1,5) = '[1,4]'::int4range</literal></entry>
12843         <entry><literal>t</literal></entry>
12844        </row>
12845
12846        <row>
12847         <entry> <literal>&lt;&gt;</literal> </entry>
12848         <entry>not equal</entry>
12849         <entry><literal>numrange(1.1,2.2) &lt;&gt; numrange(1.1,2.3)</literal></entry>
12850         <entry><literal>t</literal></entry>
12851        </row>
12852
12853        <row>
12854         <entry> <literal>&lt;</literal> </entry>
12855         <entry>less than</entry>
12856         <entry><literal>int4range(1,10) &lt; int4range(2,3)</literal></entry>
12857         <entry><literal>t</literal></entry>
12858        </row>
12859
12860        <row>
12861         <entry> <literal>&gt;</literal> </entry>
12862         <entry>greater than</entry>
12863         <entry><literal>int4range(1,10) &gt; int4range(1,5)</literal></entry>
12864         <entry><literal>t</literal></entry>
12865        </row>
12866
12867        <row>
12868         <entry> <literal>&lt;=</literal> </entry>
12869         <entry>less than or equal</entry>
12870         <entry><literal>numrange(1.1,2.2) &lt;= numrange(1.1,2.2)</literal></entry>
12871         <entry><literal>t</literal></entry>
12872        </row>
12873
12874        <row>
12875         <entry> <literal>&gt;=</literal> </entry>
12876         <entry>greater than or equal</entry>
12877         <entry><literal>numrange(1.1,2.2) &gt;= numrange(1.1,2.0)</literal></entry>
12878         <entry><literal>t</literal></entry>
12879        </row>
12880
12881        <row>
12882         <entry> <literal>@&gt;</literal> </entry>
12883         <entry>contains range</entry>
12884         <entry><literal>int4range(2,4) @&gt; int4range(2,3)</literal></entry>
12885         <entry><literal>t</literal></entry>
12886        </row>
12887
12888        <row>
12889         <entry> <literal>@&gt;</literal> </entry>
12890         <entry>contains element</entry>
12891         <entry><literal>'[2011-01-01,2011-03-01)'::tsrange @&gt; '2011-01-10'::timestamp</literal></entry>
12892         <entry><literal>t</literal></entry>
12893        </row>
12894
12895        <row>
12896         <entry> <literal>&lt;@</literal> </entry>
12897         <entry>range is contained by</entry>
12898         <entry><literal>int4range(2,4) &lt;@ int4range(1,7)</literal></entry>
12899         <entry><literal>t</literal></entry>
12900        </row>
12901
12902        <row>
12903         <entry> <literal>&lt;@</literal> </entry>
12904         <entry>element is contained by</entry>
12905         <entry><literal>42 &lt;@ int4range(1,7)</literal></entry>
12906         <entry><literal>f</literal></entry>
12907        </row>
12908
12909        <row>
12910         <entry> <literal>&amp;&amp;</literal> </entry>
12911         <entry>overlap (have points in common)</entry>
12912         <entry><literal>int8range(3,7) &amp;&amp; int8range(4,12)</literal></entry>
12913         <entry><literal>t</literal></entry>
12914        </row>
12915
12916        <row>
12917         <entry> <literal>&lt;&lt;</literal> </entry>
12918         <entry>strictly left of</entry>
12919         <entry><literal>int8range(1,10) &lt;&lt; int8range(100,110)</literal></entry>
12920         <entry><literal>t</literal></entry>
12921        </row>
12922
12923        <row>
12924         <entry> <literal>&gt;&gt;</literal> </entry>
12925         <entry>strictly right of</entry>
12926         <entry><literal>int8range(50,60) &gt;&gt; int8range(20,30)</literal></entry>
12927         <entry><literal>t</literal></entry>
12928        </row>
12929
12930        <row>
12931         <entry> <literal>&amp;&lt;</literal> </entry>
12932         <entry>does not extend to the right of</entry>
12933         <entry><literal>int8range(1,20) &amp;&lt; int8range(18,20)</literal></entry>
12934         <entry><literal>t</literal></entry>
12935        </row>
12936
12937        <row>
12938         <entry> <literal>&amp;&gt;</literal> </entry>
12939         <entry>does not extend to the left of</entry>
12940         <entry><literal>int8range(7,20) &amp;&gt; int8range(5,10)</literal></entry>
12941         <entry><literal>t</literal></entry>
12942        </row>
12943
12944        <row>
12945         <entry> <literal>-|-</literal> </entry>
12946         <entry>is adjacent to</entry>
12947         <entry><literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal></entry>
12948         <entry><literal>t</literal></entry>
12949        </row>
12950
12951        <row>
12952         <entry> <literal>+</literal> </entry>
12953         <entry>union</entry>
12954         <entry><literal>numrange(5,15) + numrange(10,20)</literal></entry>
12955         <entry><literal>[5,20)</literal></entry>
12956        </row>
12957
12958        <row>
12959         <entry> <literal>*</literal> </entry>
12960         <entry>intersection</entry>
12961         <entry><literal>int8range(5,15) * int8range(10,20)</literal></entry>
12962         <entry><literal>[10,15)</literal></entry>
12963        </row>
12964
12965        <row>
12966         <entry> <literal>-</literal> </entry>
12967         <entry>difference</entry>
12968         <entry><literal>int8range(5,15) - int8range(10,20)</literal></entry>
12969         <entry><literal>[5,10)</literal></entry>
12970        </row>
12971
12972       </tbody>
12973      </tgroup>
12974     </table>
12975
12976   <para>
12977    The simple comparison operators <literal>&lt;</literal>,
12978    <literal>&gt;</literal>, <literal>&lt;=</literal>, and
12979    <literal>&gt;=</literal> compare the lower bounds first, and only if those
12980    are equal, compare the upper bounds.  These comparisons are not usually
12981    very useful for ranges, but are provided to allow B-tree indexes to be
12982    constructed on ranges.
12983   </para>
12984
12985   <para>
12986    The left-of/right-of/adjacent operators always return false when an empty
12987    range is involved; that is, an empty range is not considered to be either
12988    before or after any other range.
12989   </para>
12990
12991   <para>
12992    The union and difference operators will fail if the resulting range would
12993    need to contain two disjoint sub-ranges, as such a range cannot be
12994    represented.
12995   </para>
12996
12997   <para>
12998    <xref linkend="range-functions-table"> shows the functions
12999    available for use with range types.
13000   </para>
13001
13002   <indexterm>
13003     <primary>lower</primary>
13004   </indexterm>
13005   <indexterm>
13006     <primary>upper</primary>
13007   </indexterm>
13008   <indexterm>
13009     <primary>isempty</primary>
13010   </indexterm>
13011   <indexterm>
13012     <primary>lower_inc</primary>
13013   </indexterm>
13014   <indexterm>
13015     <primary>upper_inc</primary>
13016   </indexterm>
13017   <indexterm>
13018     <primary>lower_inf</primary>
13019   </indexterm>
13020   <indexterm>
13021     <primary>upper_inf</primary>
13022   </indexterm>
13023
13024     <table id="range-functions-table">
13025      <title>Range Functions</title>
13026      <tgroup cols="5">
13027       <thead>
13028        <row>
13029         <entry>Function</entry>
13030         <entry>Return Type</entry>
13031         <entry>Description</entry>
13032         <entry>Example</entry>
13033         <entry>Result</entry>
13034        </row>
13035       </thead>
13036       <tbody>
13037        <row>
13038         <entry>
13039          <literal>
13040           <function>lower</function>(<type>anyrange</type>)
13041          </literal>
13042         </entry>
13043         <entry>range's element type</entry>
13044         <entry>lower bound of range</entry>
13045         <entry><literal>lower(numrange(1.1,2.2))</literal></entry>
13046         <entry><literal>1.1</literal></entry>
13047        </row>
13048        <row>
13049         <entry>
13050          <literal>
13051           <function>upper</function>(<type>anyrange</type>)
13052          </literal>
13053         </entry>
13054         <entry>range's element type</entry>
13055         <entry>upper bound of range</entry>
13056         <entry><literal>upper(numrange(1.1,2.2))</literal></entry>
13057         <entry><literal>2.2</literal></entry>
13058        </row>
13059        <row>
13060         <entry>
13061          <literal>
13062           <function>isempty</function>(<type>anyrange</type>)
13063          </literal>
13064         </entry>
13065         <entry><type>boolean</type></entry>
13066         <entry>is the range empty?</entry>
13067         <entry><literal>isempty(numrange(1.1,2.2))</literal></entry>
13068         <entry><literal>false</literal></entry>
13069        </row>
13070        <row>
13071         <entry>
13072          <literal>
13073           <function>lower_inc</function>(<type>anyrange</type>)
13074          </literal>
13075         </entry>
13076         <entry><type>boolean</type></entry>
13077         <entry>is the lower bound inclusive?</entry>
13078         <entry><literal>lower_inc(numrange(1.1,2.2))</literal></entry>
13079         <entry><literal>true</literal></entry>
13080        </row>
13081        <row>
13082         <entry>
13083          <literal>
13084           <function>upper_inc</function>(<type>anyrange</type>)
13085          </literal>
13086         </entry>
13087         <entry><type>boolean</type></entry>
13088         <entry>is the upper bound inclusive?</entry>
13089         <entry><literal>upper_inc(numrange(1.1,2.2))</literal></entry>
13090         <entry><literal>false</literal></entry>
13091        </row>
13092        <row>
13093         <entry>
13094          <literal>
13095           <function>lower_inf</function>(<type>anyrange</type>)
13096          </literal>
13097         </entry>
13098         <entry><type>boolean</type></entry>
13099         <entry>is the lower bound infinite?</entry>
13100         <entry><literal>lower_inf('(,)'::daterange)</literal></entry>
13101         <entry><literal>true</literal></entry>
13102        </row>
13103        <row>
13104         <entry>
13105          <literal>
13106           <function>upper_inf</function>(<type>anyrange</type>)
13107          </literal>
13108         </entry>
13109         <entry><type>boolean</type></entry>
13110         <entry>is the upper bound infinite?</entry>
13111         <entry><literal>upper_inf('(,)'::daterange)</literal></entry>
13112         <entry><literal>true</literal></entry>
13113        </row>
13114        <row>
13115         <entry>
13116          <literal>
13117           <function>range_merge</function>(<type>anyrange</type>, <type>anyrange</type>)
13118          </literal>
13119         </entry>
13120         <entry><type>anyrange</type></entry>
13121         <entry>the smallest range which includes both of the given ranges</entry>
13122         <entry><literal>range_merge('[1,2)'::int4range, '[3,4)'::int4range)</literal></entry>
13123         <entry><literal>[1,4)</literal></entry>
13124        </row>
13125       </tbody>
13126      </tgroup>
13127     </table>
13128
13129   <para>
13130    The <function>lower</> and  <function>upper</> functions return null
13131    if the range is empty or the requested bound is infinite.
13132    The <function>lower_inc</function>, <function>upper_inc</function>,
13133    <function>lower_inf</function>, and <function>upper_inf</function>
13134    functions all return false for an empty range.
13135   </para>
13136   </sect1>
13137
13138  <sect1 id="functions-aggregate">
13139   <title>Aggregate Functions</title>
13140
13141   <indexterm zone="functions-aggregate">
13142    <primary>aggregate function</primary>
13143    <secondary>built-in</secondary>
13144   </indexterm>
13145
13146   <para>
13147    <firstterm>Aggregate functions</firstterm> compute a single result
13148    from a set of input values.  The built-in normal aggregate functions
13149    are listed in
13150    <xref linkend="functions-aggregate-table"> and
13151    <xref linkend="functions-aggregate-statistics-table">.
13152    The built-in ordered-set aggregate functions
13153    are listed in <xref linkend="functions-orderedset-table"> and
13154    <xref linkend="functions-hypothetical-table">.  Grouping operations,
13155    which are closely related to aggregate functions, are listed in
13156    <xref linkend="functions-grouping-table">.
13157    The special syntax considerations for aggregate
13158    functions are explained in <xref linkend="syntax-aggregates">.
13159    Consult <xref linkend="tutorial-agg"> for additional introductory
13160    information.
13161   </para>
13162
13163   <table id="functions-aggregate-table">
13164    <title>General-Purpose Aggregate Functions</title>
13165
13166    <tgroup cols="5">
13167     <thead>
13168      <row>
13169       <entry>Function</entry>
13170       <entry>Argument Type(s)</entry>
13171       <entry>Return Type</entry>
13172       <entry>Partial Mode</entry>
13173       <entry>Description</entry>
13174      </row>
13175     </thead>
13176
13177     <tbody>
13178      <row>
13179       <entry>
13180        <indexterm>
13181         <primary>array_agg</primary>
13182        </indexterm>
13183        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
13184       </entry>
13185       <entry>
13186        any non-array type
13187       </entry>
13188       <entry>
13189        array of the argument type
13190       </entry>
13191       <entry>No</entry>
13192       <entry>input values, including nulls, concatenated into an array</entry>
13193      </row>
13194
13195      <row>
13196       <entry>
13197        <function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
13198       </entry>
13199       <entry>
13200        any array type
13201       </entry>
13202       <entry>
13203        same as argument data type
13204       </entry>
13205       <entry>No</entry>
13206       <entry>input arrays concatenated into array of one higher dimension
13207        (inputs must all have same dimensionality,
13208         and cannot be empty or NULL)</entry>
13209      </row>
13210
13211      <row>
13212       <entry>
13213        <indexterm>
13214         <primary>average</primary>
13215        </indexterm>
13216        <indexterm>
13217         <primary>avg</primary>
13218        </indexterm>
13219        <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
13220       </entry>
13221       <entry>
13222        <type>smallint</type>, <type>int</type>,
13223        <type>bigint</type>, <type>real</type>, <type>double
13224        precision</type>, <type>numeric</type>, or <type>interval</type>
13225       </entry>
13226       <entry>
13227        <type>numeric</type> for any integer-type argument,
13228        <type>double precision</type> for a floating-point argument,
13229        otherwise the same as the argument data type
13230       </entry>
13231       <entry>Yes</entry>
13232       <entry>the average (arithmetic mean) of all input values</entry>
13233      </row>
13234
13235      <row>
13236       <entry>
13237        <indexterm>
13238         <primary>bit_and</primary>
13239        </indexterm>
13240        <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
13241       </entry>
13242       <entry>
13243        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
13244        <type>bit</type>
13245       </entry>
13246       <entry>
13247         same as argument data type
13248       </entry>
13249       <entry>Yes</entry>
13250       <entry>the bitwise AND of all non-null input values, or null if none</entry>
13251      </row>
13252
13253      <row>
13254       <entry>
13255        <indexterm>
13256         <primary>bit_or</primary>
13257        </indexterm>
13258        <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
13259       </entry>
13260       <entry>
13261        <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
13262        <type>bit</type>
13263       </entry>
13264       <entry>
13265         same as argument data type
13266       </entry>
13267       <entry>Yes</entry>
13268       <entry>the bitwise OR of all non-null input values, or null if none</entry>
13269      </row>
13270
13271      <row>
13272       <entry>
13273        <indexterm>
13274         <primary>bool_and</primary>
13275        </indexterm>
13276        <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
13277       </entry>
13278       <entry>
13279        <type>bool</type>
13280       </entry>
13281       <entry>
13282        <type>bool</type>
13283       </entry>
13284       <entry>Yes</entry>
13285       <entry>true if all input values are true, otherwise false</entry>
13286      </row>
13287
13288      <row>
13289       <entry>
13290        <indexterm>
13291         <primary>bool_or</primary>
13292        </indexterm>
13293        <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
13294       </entry>
13295       <entry>
13296        <type>bool</type>
13297       </entry>
13298       <entry>
13299        <type>bool</type>
13300       </entry>
13301       <entry>Yes</entry>
13302       <entry>true if at least one input value is true, otherwise false</entry>
13303      </row>
13304
13305      <row>
13306       <entry>
13307        <indexterm>
13308         <primary>count</primary>
13309        </indexterm>
13310        <function>count(*)</function>
13311       </entry>
13312       <entry></entry>
13313       <entry><type>bigint</type></entry>
13314       <entry>Yes</entry>
13315       <entry>number of input rows</entry>
13316      </row>
13317
13318      <row>
13319       <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
13320       <entry>any</entry>
13321       <entry><type>bigint</type></entry>
13322       <entry>Yes</entry>
13323       <entry>
13324        number of input rows for which the value of <replaceable
13325        class="parameter">expression</replaceable> is not null
13326       </entry>
13327      </row>
13328
13329      <row>
13330       <entry>
13331        <indexterm>
13332         <primary>every</primary>
13333        </indexterm>
13334        <function>every(<replaceable class="parameter">expression</replaceable>)</function>
13335       </entry>
13336       <entry>
13337        <type>bool</type>
13338       </entry>
13339       <entry>
13340        <type>bool</type>
13341       </entry>
13342       <entry>Yes</entry>
13343       <entry>equivalent to <function>bool_and</function></entry>
13344      </row>
13345
13346      <row>
13347       <entry>
13348        <indexterm>
13349         <primary>json_agg</primary>
13350        </indexterm>
13351        <function>json_agg(<replaceable class="parameter">expression</replaceable>)</function>
13352       </entry>
13353       <entry>
13354        <type>any</type>
13355       </entry>
13356       <entry>
13357        <type>json</type>
13358       </entry>
13359       <entry>No</entry>
13360       <entry>aggregates values as a JSON array</entry>
13361      </row>
13362
13363      <row>
13364       <entry>
13365        <indexterm>
13366         <primary>jsonb_agg</primary>
13367        </indexterm>
13368        <function>jsonb_agg(<replaceable class="parameter">expression</replaceable>)</function>
13369       </entry>
13370       <entry>
13371        <type>any</type>
13372       </entry>
13373       <entry>
13374        <type>jsonb</type>
13375       </entry>
13376       <entry>No</entry>
13377       <entry>aggregates values as a JSON array</entry>
13378      </row>
13379
13380      <row>
13381       <entry>
13382        <indexterm>
13383         <primary>json_object_agg</primary>
13384        </indexterm>
13385        <function>json_object_agg(<replaceable class="parameter">name</replaceable>, <replaceable class="parameter">value</replaceable>)</function>
13386       </entry>
13387       <entry>
13388        <type>(any, any)</type>
13389       </entry>
13390       <entry>
13391        <type>json</type>
13392       </entry>
13393       <entry>No</entry>
13394       <entry>aggregates name/value pairs as a JSON object</entry>
13395      </row>
13396
13397      <row>
13398       <entry>
13399        <indexterm>
13400         <primary>jsonb_object_agg</primary>
13401        </indexterm>
13402        <function>jsonb_object_agg(<replaceable class="parameter">name</replaceable>, <replaceable class="parameter">value</replaceable>)</function>
13403       </entry>
13404       <entry>
13405        <type>(any, any)</type>
13406       </entry>
13407       <entry>
13408        <type>jsonb</type>
13409       </entry>
13410       <entry>No</entry>
13411       <entry>aggregates name/value pairs as a JSON object</entry>
13412      </row>
13413
13414      <row>
13415       <entry>
13416        <indexterm>
13417         <primary>max</primary>
13418        </indexterm>
13419        <function>max(<replaceable class="parameter">expression</replaceable>)</function>
13420       </entry>
13421       <entry>any numeric, string, date/time, network, or enum type,
13422              or arrays of these types</entry>
13423       <entry>same as argument type</entry>
13424       <entry>Yes</entry>
13425       <entry>
13426        maximum value of <replaceable
13427        class="parameter">expression</replaceable> across all input
13428        values
13429       </entry>
13430      </row>
13431
13432      <row>
13433       <entry>
13434        <indexterm>
13435         <primary>min</primary>
13436        </indexterm>
13437        <function>min(<replaceable class="parameter">expression</replaceable>)</function>
13438       </entry>
13439       <entry>any numeric, string, date/time, network, or enum type,
13440              or arrays of these types</entry>
13441       <entry>same as argument type</entry>
13442       <entry>Yes</entry>
13443       <entry>
13444        minimum value of <replaceable
13445        class="parameter">expression</replaceable> across all input
13446        values
13447       </entry>
13448      </row>
13449
13450      <row>
13451       <entry>
13452        <indexterm>
13453         <primary>string_agg</primary>
13454        </indexterm>
13455        <function>
13456          string_agg(<replaceable class="parameter">expression</replaceable>,
13457                     <replaceable class="parameter">delimiter</replaceable>)
13458        </function>
13459       </entry>
13460       <entry>
13461        (<type>text</type>, <type>text</type>) or (<type>bytea</type>, <type>bytea</type>)
13462       </entry>
13463       <entry>
13464        same as argument types
13465       </entry>
13466       <entry>No</entry>
13467       <entry>input values concatenated into a string, separated by delimiter</entry>
13468      </row>
13469
13470      <row>
13471       <entry>
13472        <indexterm>
13473         <primary>sum</primary>
13474        </indexterm>
13475        <function>sum(<replaceable class="parameter">expression</replaceable>)</function>
13476       </entry>
13477       <entry>
13478        <type>smallint</type>, <type>int</type>,
13479        <type>bigint</type>, <type>real</type>, <type>double
13480        precision</type>, <type>numeric</type>,
13481        <type>interval</type>, or <type>money</>
13482       </entry>
13483       <entry>
13484        <type>bigint</type> for <type>smallint</type> or
13485        <type>int</type> arguments, <type>numeric</type> for
13486        <type>bigint</type> arguments, otherwise the same as the
13487        argument data type
13488       </entry>
13489       <entry>Yes</entry>
13490       <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
13491      </row>
13492
13493      <row>
13494       <entry>
13495        <indexterm>
13496         <primary>xmlagg</primary>
13497        </indexterm>
13498        <function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
13499       </entry>
13500       <entry>
13501        <type>xml</type>
13502       </entry>
13503       <entry>
13504        <type>xml</type>
13505       </entry>
13506       <entry>No</entry>
13507       <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
13508      </row>
13509     </tbody>
13510    </tgroup>
13511   </table>
13512
13513   <para>
13514    It should be noted that except for <function>count</function>,
13515    these functions return a null value when no rows are selected.  In
13516    particular, <function>sum</function> of no rows returns null, not
13517    zero as one might expect, and <function>array_agg</function>
13518    returns null rather than an empty array when there are no input
13519    rows.  The <function>coalesce</function> function can be used to
13520    substitute zero or an empty array for null when necessary.
13521   </para>
13522
13523   <para>
13524    Aggregate functions which support <firstterm>Partial Mode</firstterm>
13525    are eligible to participate in various optimizations, such as parallel
13526    aggregation.
13527   </para>
13528
13529   <note>
13530     <indexterm>
13531       <primary>ANY</primary>
13532     </indexterm>
13533     <indexterm>
13534       <primary>SOME</primary>
13535     </indexterm>
13536     <para>
13537       Boolean aggregates <function>bool_and</function> and
13538       <function>bool_or</function> correspond to standard SQL aggregates
13539       <function>every</function> and <function>any</function> or
13540       <function>some</function>.
13541       As for <function>any</function> and <function>some</function>,
13542       it seems that there is an ambiguity built into the standard syntax:
13543 <programlisting>
13544 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
13545 </programlisting>
13546       Here <function>ANY</function> can be considered either as introducing
13547       a subquery, or as being an aggregate function, if the subquery
13548       returns one row with a Boolean value.
13549       Thus the standard name cannot be given to these aggregates.
13550     </para>
13551   </note>
13552
13553   <note>
13554    <para>
13555     Users accustomed to working with other SQL database management
13556     systems might be disappointed by the performance of the
13557     <function>count</function> aggregate when it is applied to the
13558     entire table. A query like:
13559 <programlisting>
13560 SELECT count(*) FROM sometable;
13561 </programlisting>
13562     will require effort proportional to the size of the table:
13563     <productname>PostgreSQL</productname> will need to scan either the
13564     entire table or the entirety of an index which includes all rows in
13565     the table.
13566    </para>
13567   </note>
13568
13569   <para>
13570    The aggregate functions <function>array_agg</function>,
13571    <function>json_agg</function>, <function>jsonb_agg</function>,
13572    <function>json_object_agg</function>, <function>jsonb_object_agg</function>,
13573    <function>string_agg</function>,
13574    and <function>xmlagg</function>, as well as similar user-defined
13575    aggregate functions, produce meaningfully different result values
13576    depending on the order of the input values.  This ordering is
13577    unspecified by default, but can be controlled by writing an
13578    <literal>ORDER BY</> clause within the aggregate call, as shown in
13579    <xref linkend="syntax-aggregates">.
13580    Alternatively, supplying the input values from a sorted subquery
13581    will usually work.  For example:
13582
13583 <screen><![CDATA[
13584 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
13585 ]]></screen>
13586
13587    Beware that this approach can fail if the outer query level contains
13588    additional processing, such as a join, because that might cause the
13589    subquery's output to be reordered before the aggregate is computed.
13590   </para>
13591
13592   <para>
13593    <xref linkend="functions-aggregate-statistics-table"> shows
13594    aggregate functions typically used in statistical analysis.
13595    (These are separated out merely to avoid cluttering the listing
13596    of more-commonly-used aggregates.)  Where the description mentions
13597    <replaceable class="parameter">N</replaceable>, it means the
13598    number of input rows for which all the input expressions are non-null.
13599    In all cases, null is returned if the computation is meaningless,
13600    for example when <replaceable class="parameter">N</replaceable> is zero.
13601   </para>
13602
13603   <indexterm>
13604    <primary>statistics</primary>
13605   </indexterm>
13606   <indexterm>
13607    <primary>linear regression</primary>
13608   </indexterm>
13609
13610   <table id="functions-aggregate-statistics-table">
13611    <title>Aggregate Functions for Statistics</title>
13612
13613    <tgroup cols="5">
13614     <thead>
13615      <row>
13616       <entry>Function</entry>
13617       <entry>Argument Type</entry>
13618       <entry>Return Type</entry>
13619       <entry>Partial Mode</entry>
13620       <entry>Description</entry>
13621      </row>
13622     </thead>
13623
13624     <tbody>
13625
13626      <row>
13627       <entry>
13628        <indexterm>
13629         <primary>correlation</primary>
13630        </indexterm>
13631        <indexterm>
13632         <primary>corr</primary>
13633        </indexterm>
13634        <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13635       </entry>
13636       <entry>
13637        <type>double precision</type>
13638       </entry>
13639       <entry>
13640        <type>double precision</type>
13641       </entry>
13642       <entry>Yes</entry>
13643       <entry>correlation coefficient</entry>
13644      </row>
13645
13646      <row>
13647       <entry>
13648        <indexterm>
13649         <primary>covariance</primary>
13650         <secondary>population</secondary>
13651        </indexterm>
13652        <indexterm>
13653         <primary>covar_pop</primary>
13654        </indexterm>
13655        <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13656       </entry>
13657       <entry>
13658        <type>double precision</type>
13659       </entry>
13660       <entry>
13661        <type>double precision</type>
13662       </entry>
13663       <entry>Yes</entry>
13664       <entry>population covariance</entry>
13665      </row>
13666
13667      <row>
13668       <entry>
13669        <indexterm>
13670         <primary>covariance</primary>
13671         <secondary>sample</secondary>
13672        </indexterm>
13673        <indexterm>
13674         <primary>covar_samp</primary>
13675        </indexterm>
13676        <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13677       </entry>
13678       <entry>
13679        <type>double precision</type>
13680       </entry>
13681       <entry>
13682        <type>double precision</type>
13683       </entry>
13684       <entry>Yes</entry>
13685       <entry>sample covariance</entry>
13686      </row>
13687
13688      <row>
13689       <entry>
13690        <indexterm>
13691         <primary>regr_avgx</primary>
13692        </indexterm>
13693        <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13694       </entry>
13695       <entry>
13696        <type>double precision</type>
13697       </entry>
13698       <entry>
13699        <type>double precision</type>
13700       </entry>
13701       <entry>Yes</entry>
13702       <entry>average of the independent variable
13703       (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
13704      </row>
13705
13706      <row>
13707       <entry>
13708        <indexterm>
13709         <primary>regr_avgy</primary>
13710        </indexterm>
13711        <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13712       </entry>
13713       <entry>
13714        <type>double precision</type>
13715       </entry>
13716       <entry>
13717        <type>double precision</type>
13718       </entry>
13719       <entry>Yes</entry>
13720       <entry>average of the dependent variable
13721       (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
13722      </row>
13723
13724      <row>
13725       <entry>
13726        <indexterm>
13727         <primary>regr_count</primary>
13728        </indexterm>
13729        <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13730       </entry>
13731       <entry>
13732        <type>double precision</type>
13733       </entry>
13734       <entry>
13735        <type>bigint</type>
13736       </entry>
13737       <entry>Yes</entry>
13738       <entry>number of input rows in which both expressions are nonnull</entry>
13739      </row>
13740
13741      <row>
13742       <entry>
13743        <indexterm>
13744         <primary>regression intercept</primary>
13745        </indexterm>
13746        <indexterm>
13747         <primary>regr_intercept</primary>
13748        </indexterm>
13749        <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13750       </entry>
13751       <entry>
13752        <type>double precision</type>
13753       </entry>
13754       <entry>
13755        <type>double precision</type>
13756       </entry>
13757       <entry>Yes</entry>
13758       <entry>y-intercept of the least-squares-fit linear equation
13759       determined by the (<replaceable
13760       class="parameter">X</replaceable>, <replaceable
13761       class="parameter">Y</replaceable>) pairs</entry>
13762      </row>
13763
13764      <row>
13765       <entry>
13766        <indexterm>
13767         <primary>regr_r2</primary>
13768        </indexterm>
13769        <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13770       </entry>
13771       <entry>
13772        <type>double precision</type>
13773       </entry>
13774       <entry>
13775        <type>double precision</type>
13776       </entry>
13777       <entry>Yes</entry>
13778       <entry>square of the correlation coefficient</entry>
13779      </row>
13780
13781      <row>
13782       <entry>
13783        <indexterm>
13784         <primary>regression slope</primary>
13785        </indexterm>
13786        <indexterm>
13787         <primary>regr_slope</primary>
13788        </indexterm>
13789        <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13790       </entry>
13791       <entry>
13792        <type>double precision</type>
13793       </entry>
13794       <entry>
13795        <type>double precision</type>
13796       </entry>
13797       <entry>Yes</entry>
13798       <entry>slope of the least-squares-fit linear equation determined
13799       by the (<replaceable class="parameter">X</replaceable>,
13800       <replaceable class="parameter">Y</replaceable>) pairs</entry>
13801      </row>
13802
13803      <row>
13804       <entry>
13805        <indexterm>
13806         <primary>regr_sxx</primary>
13807        </indexterm>
13808        <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13809       </entry>
13810       <entry>
13811        <type>double precision</type>
13812       </entry>
13813       <entry>
13814        <type>double precision</type>
13815       </entry>
13816       <entry>Yes</entry>
13817       <entry><literal>sum(<replaceable
13818       class="parameter">X</replaceable>^2) - sum(<replaceable
13819       class="parameter">X</replaceable>)^2/<replaceable
13820       class="parameter">N</replaceable></literal> (<quote>sum of
13821       squares</quote> of the independent variable)</entry>
13822      </row>
13823
13824      <row>
13825       <entry>
13826        <indexterm>
13827         <primary>regr_sxy</primary>
13828        </indexterm>
13829        <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13830       </entry>
13831       <entry>
13832        <type>double precision</type>
13833       </entry>
13834       <entry>
13835        <type>double precision</type>
13836       </entry>
13837       <entry>Yes</entry>
13838       <entry><literal>sum(<replaceable
13839       class="parameter">X</replaceable>*<replaceable
13840       class="parameter">Y</replaceable>) - sum(<replaceable
13841       class="parameter">X</replaceable>) * sum(<replaceable
13842       class="parameter">Y</replaceable>)/<replaceable
13843       class="parameter">N</replaceable></literal> (<quote>sum of
13844       products</quote> of independent times dependent
13845       variable)</entry>
13846      </row>
13847
13848      <row>
13849       <entry>
13850        <indexterm>
13851         <primary>regr_syy</primary>
13852        </indexterm>
13853        <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
13854       </entry>
13855       <entry>
13856        <type>double precision</type>
13857       </entry>
13858       <entry>
13859        <type>double precision</type>
13860       </entry>
13861       <entry>Yes</entry>
13862       <entry><literal>sum(<replaceable
13863       class="parameter">Y</replaceable>^2) - sum(<replaceable
13864       class="parameter">Y</replaceable>)^2/<replaceable
13865       class="parameter">N</replaceable></literal> (<quote>sum of
13866       squares</quote> of the dependent variable)</entry>
13867      </row>
13868
13869      <row>
13870       <entry>
13871        <indexterm>
13872         <primary>standard deviation</primary>
13873        </indexterm>
13874        <indexterm>
13875         <primary>stddev</primary>
13876        </indexterm>
13877        <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
13878       </entry>
13879       <entry>
13880        <type>smallint</type>, <type>int</type>,
13881        <type>bigint</type>, <type>real</type>, <type>double
13882        precision</type>, or <type>numeric</type>
13883       </entry>
13884       <entry>
13885        <type>double precision</type> for floating-point arguments,
13886        otherwise <type>numeric</type>
13887       </entry>
13888       <entry>Yes</entry>
13889       <entry>historical alias for <function>stddev_samp</function></entry>
13890      </row>
13891
13892      <row>
13893       <entry>
13894        <indexterm>
13895         <primary>standard deviation</primary>
13896         <secondary>population</secondary>
13897        </indexterm>
13898        <indexterm>
13899         <primary>stddev_pop</primary>
13900        </indexterm>
13901        <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
13902       </entry>
13903       <entry>
13904        <type>smallint</type>, <type>int</type>,
13905        <type>bigint</type>, <type>real</type>, <type>double
13906        precision</type>, or <type>numeric</type>
13907       </entry>
13908       <entry>
13909        <type>double precision</type> for floating-point arguments,
13910        otherwise <type>numeric</type>
13911       </entry>
13912       <entry>Yes</entry>
13913       <entry>population standard deviation of the input values</entry>
13914      </row>
13915
13916      <row>
13917       <entry>
13918        <indexterm>
13919         <primary>standard deviation</primary>
13920         <secondary>sample</secondary>
13921        </indexterm>
13922        <indexterm>
13923         <primary>stddev_samp</primary>
13924        </indexterm>
13925        <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
13926       </entry>
13927       <entry>
13928        <type>smallint</type>, <type>int</type>,
13929        <type>bigint</type>, <type>real</type>, <type>double
13930        precision</type>, or <type>numeric</type>
13931       </entry>
13932       <entry>
13933        <type>double precision</type> for floating-point arguments,
13934        otherwise <type>numeric</type>
13935       </entry>
13936       <entry>Yes</entry>
13937       <entry>sample standard deviation of the input values</entry>
13938      </row>
13939
13940      <row>
13941       <entry>
13942        <indexterm>
13943         <primary>variance</primary>
13944        </indexterm>
13945        <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
13946       </entry>
13947       <entry>
13948        <type>smallint</type>, <type>int</type>,
13949        <type>bigint</type>, <type>real</type>, <type>double
13950        precision</type>, or <type>numeric</type>
13951       </entry>
13952       <entry>
13953        <type>double precision</type> for floating-point arguments,
13954        otherwise <type>numeric</type>
13955       </entry>
13956       <entry>Yes</entry>
13957       <entry>historical alias for <function>var_samp</function></entry>
13958      </row>
13959
13960      <row>
13961       <entry>
13962        <indexterm>
13963         <primary>variance</primary>
13964         <secondary>population</secondary>
13965        </indexterm>
13966        <indexterm>
13967         <primary>var_pop</primary>
13968        </indexterm>
13969        <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
13970       </entry>
13971       <entry>
13972        <type>smallint</type>, <type>int</type>,
13973        <type>bigint</type>, <type>real</type>, <type>double
13974        precision</type>, or <type>numeric</type>
13975       </entry>
13976       <entry>
13977        <type>double precision</type> for floating-point arguments,
13978        otherwise <type>numeric</type>
13979       </entry>
13980       <entry>Yes</entry>
13981       <entry>population variance of the input values (square of the population standard deviation)</entry>
13982      </row>
13983
13984      <row>
13985       <entry>
13986        <indexterm>
13987         <primary>variance</primary>
13988         <secondary>sample</secondary>
13989        </indexterm>
13990        <indexterm>
13991         <primary>var_samp</primary>
13992        </indexterm>
13993        <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
13994       </entry>
13995       <entry>
13996        <type>smallint</type>, <type>int</type>,
13997        <type>bigint</type>, <type>real</type>, <type>double
13998        precision</type>, or <type>numeric</type>
13999       </entry>
14000       <entry>
14001        <type>double precision</type> for floating-point arguments,
14002        otherwise <type>numeric</type>
14003       </entry>
14004       <entry>Yes</entry>
14005       <entry>sample variance of the input values (square of the sample standard deviation)</entry>
14006      </row>
14007     </tbody>
14008    </tgroup>
14009   </table>
14010
14011   <para>
14012    <xref linkend="functions-orderedset-table"> shows some
14013    aggregate functions that use the <firstterm>ordered-set aggregate</>
14014    syntax.  These functions are sometimes referred to as <quote>inverse
14015    distribution</> functions.
14016   </para>
14017
14018   <indexterm>
14019    <primary>ordered-set aggregate</primary>
14020    <secondary>built-in</secondary>
14021   </indexterm>
14022   <indexterm>
14023    <primary>inverse distribution</primary>
14024   </indexterm>
14025
14026   <table id="functions-orderedset-table">
14027    <title>Ordered-Set Aggregate Functions</title>
14028
14029    <tgroup cols="6">
14030     <thead>
14031      <row>
14032       <entry>Function</entry>
14033       <entry>Direct Argument Type(s)</entry>
14034       <entry>Aggregated Argument Type(s)</entry>
14035       <entry>Return Type</entry>
14036       <entry>Partial Mode</entry>
14037       <entry>Description</entry>
14038      </row>
14039     </thead>
14040
14041     <tbody>
14042
14043      <row>
14044       <entry>
14045        <indexterm>
14046         <primary>mode</primary>
14047         <secondary>statistical</secondary>
14048        </indexterm>
14049        <function>mode() WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
14050       </entry>
14051       <entry>
14052       </entry>
14053       <entry>
14054        any sortable type
14055       </entry>
14056       <entry>
14057        same as sort expression
14058       </entry>
14059       <entry>No</entry>
14060       <entry>
14061        returns the most frequent input value (arbitrarily choosing the first
14062        one if there are multiple equally-frequent results)
14063       </entry>
14064      </row>
14065
14066      <row>
14067       <entry>
14068        <indexterm>
14069         <primary>percentile</primary>
14070         <secondary>continuous</secondary>
14071        </indexterm>
14072        <function>percentile_cont(<replaceable class="parameter">fraction</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
14073       </entry>
14074       <entry>
14075        <type>double precision</type>
14076       </entry>
14077       <entry>
14078        <type>double precision</type> or <type>interval</type>
14079       </entry>
14080       <entry>
14081        same as sort expression
14082       </entry>
14083       <entry>No</entry>
14084       <entry>
14085        continuous percentile: returns a value corresponding to the specified
14086        fraction in the ordering, interpolating between adjacent input items if
14087        needed
14088       </entry>
14089      </row>
14090
14091      <row>
14092       <entry>
14093        <function>percentile_cont(<replaceable class="parameter">fractions</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
14094       </entry>
14095       <entry>
14096        <type>double precision[]</type>
14097       </entry>
14098       <entry>
14099        <type>double precision</type> or <type>interval</type>
14100       </entry>
14101       <entry>
14102        array of sort expression's type
14103       </entry>
14104       <entry>No</entry>
14105       <entry>
14106        multiple continuous percentile: returns an array of results matching
14107        the shape of the <replaceable>fractions</replaceable> parameter, with each
14108        non-null element replaced by the value corresponding to that percentile
14109       </entry>
14110      </row>
14111
14112      <row>
14113       <entry>
14114        <indexterm>
14115         <primary>percentile</primary>
14116         <secondary>discrete</secondary>
14117        </indexterm>
14118        <function>percentile_disc(<replaceable class="parameter">fraction</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
14119       </entry>
14120       <entry>
14121        <type>double precision</type>
14122       </entry>
14123       <entry>
14124        any sortable type
14125       </entry>
14126       <entry>
14127        same as sort expression
14128       </entry>
14129       <entry>No</entry>
14130       <entry>
14131        discrete percentile: returns the first input value whose position in
14132        the ordering equals or exceeds the specified fraction
14133       </entry>
14134      </row>
14135
14136      <row>
14137       <entry>
14138        <function>percentile_disc(<replaceable class="parameter">fractions</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
14139       </entry>
14140       <entry>
14141        <type>double precision[]</type>
14142       </entry>
14143       <entry>
14144        any sortable type
14145       </entry>
14146       <entry>
14147        array of sort expression's type
14148       </entry>
14149       <entry>No</entry>
14150       <entry>
14151        multiple discrete percentile: returns an array of results matching the
14152        shape of the <replaceable>fractions</replaceable> parameter, with each non-null
14153        element replaced by the input value corresponding to that percentile
14154       </entry>
14155      </row>
14156
14157     </tbody>
14158    </tgroup>
14159   </table>
14160
14161   <para>
14162    All the aggregates listed in <xref linkend="functions-orderedset-table">
14163    ignore null values in their sorted input.  For those that take
14164    a <replaceable>fraction</replaceable> parameter, the fraction value must be
14165    between 0 and 1; an error is thrown if not.  However, a null fraction value
14166    simply produces a null result.
14167   </para>
14168
14169   <indexterm>
14170    <primary>hypothetical-set aggregate</primary>
14171    <secondary>built-in</secondary>
14172   </indexterm>
14173
14174   <para>
14175    Each of the aggregates listed in
14176    <xref linkend="functions-hypothetical-table"> is associated with a
14177    window function of the same name defined in
14178    <xref linkend="functions-window">.  In each case, the aggregate result
14179    is the value that the associated window function would have
14180    returned for the <quote>hypothetical</> row constructed from
14181    <replaceable>args</replaceable>, if such a row had been added to the sorted
14182    group of rows computed from the <replaceable>sorted_args</replaceable>.
14183   </para>
14184
14185   <table id="functions-hypothetical-table">
14186    <title>Hypothetical-Set Aggregate Functions</title>
14187
14188    <tgroup cols="6">
14189     <thead>
14190      <row>
14191       <entry>Function</entry>
14192       <entry>Direct Argument Type(s)</entry>
14193       <entry>Aggregated Argument Type(s)</entry>
14194       <entry>Return Type</entry>
14195       <entry>Partial Mode</entry>
14196       <entry>Description</entry>
14197      </row>
14198     </thead>
14199
14200     <tbody>
14201
14202      <row>
14203       <entry>
14204        <indexterm>
14205         <primary>rank</primary>
14206         <secondary>hypothetical</secondary>
14207        </indexterm>
14208        <function>rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
14209       </entry>
14210       <entry>
14211        <literal>VARIADIC</> <type>"any"</type>
14212       </entry>
14213       <entry>
14214        <literal>VARIADIC</> <type>"any"</type>
14215       </entry>
14216       <entry>
14217        <type>bigint</type>
14218       </entry>
14219       <entry>No</entry>
14220       <entry>
14221        rank of the hypothetical row, with gaps for duplicate rows
14222       </entry>
14223      </row>
14224
14225      <row>
14226       <entry>
14227        <indexterm>
14228         <primary>dense_rank</primary>
14229         <secondary>hypothetical</secondary>
14230        </indexterm>
14231        <function>dense_rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
14232       </entry>
14233       <entry>
14234        <literal>VARIADIC</> <type>"any"</type>
14235       </entry>
14236       <entry>
14237        <literal>VARIADIC</> <type>"any"</type>
14238       </entry>
14239       <entry>
14240        <type>bigint</type>
14241       </entry>
14242       <entry>No</entry>
14243       <entry>
14244        rank of the hypothetical row, without gaps
14245       </entry>
14246      </row>
14247
14248      <row>
14249       <entry>
14250        <indexterm>
14251         <primary>percent_rank</primary>
14252         <secondary>hypothetical</secondary>
14253        </indexterm>
14254        <function>percent_rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
14255       </entry>
14256       <entry>
14257        <literal>VARIADIC</> <type>"any"</type>
14258       </entry>
14259       <entry>
14260        <literal>VARIADIC</> <type>"any"</type>
14261       </entry>
14262       <entry>
14263        <type>double precision</type>
14264       </entry>
14265       <entry>No</entry>
14266       <entry>
14267        relative rank of the hypothetical row, ranging from 0 to 1
14268       </entry>
14269      </row>
14270
14271      <row>
14272       <entry>
14273        <indexterm>
14274         <primary>cume_dist</primary>
14275         <secondary>hypothetical</secondary>
14276        </indexterm>
14277        <function>cume_dist(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
14278       </entry>
14279       <entry>
14280        <literal>VARIADIC</> <type>"any"</type>
14281       </entry>
14282       <entry>
14283        <literal>VARIADIC</> <type>"any"</type>
14284       </entry>
14285       <entry>
14286        <type>double precision</type>
14287       </entry>
14288       <entry>No</entry>
14289       <entry>
14290        relative rank of the hypothetical row, ranging from
14291        1/<replaceable>N</> to 1
14292       </entry>
14293      </row>
14294
14295     </tbody>
14296    </tgroup>
14297   </table>
14298
14299   <para>
14300    For each of these hypothetical-set aggregates, the list of direct arguments
14301    given in <replaceable>args</replaceable> must match the number and types of
14302    the aggregated arguments given in <replaceable>sorted_args</replaceable>.
14303    Unlike most built-in aggregates, these aggregates are not strict, that is
14304    they do not drop input rows containing nulls.  Null values sort according
14305    to the rule specified in the <literal>ORDER BY</> clause.
14306   </para>
14307
14308   <table id="functions-grouping-table">
14309    <title>Grouping Operations</title>
14310
14311    <tgroup cols="3">
14312     <thead>
14313      <row>
14314       <entry>Function</entry>
14315       <entry>Return Type</entry>
14316       <entry>Description</entry>
14317      </row>
14318     </thead>
14319
14320     <tbody>
14321
14322      <row>
14323       <entry>
14324        <indexterm>
14325         <primary>GROUPING</primary>
14326        </indexterm>
14327        <function>GROUPING(<replaceable class="parameter">args...</replaceable>)</function>
14328       </entry>
14329       <entry>
14330        <type>integer</type>
14331       </entry>
14332       <entry>
14333        Integer bit mask indicating which arguments are not being included in the current
14334        grouping set
14335       </entry>
14336      </row>
14337     </tbody>
14338    </tgroup>
14339   </table>
14340
14341    <para>
14342     Grouping operations are used in conjunction with grouping sets (see
14343     <xref linkend="queries-grouping-sets">) to distinguish result rows.  The
14344     arguments to the <literal>GROUPING</> operation are not actually evaluated,
14345     but they must match exactly expressions given in the <literal>GROUP BY</>
14346     clause of the associated query level.  Bits are assigned with the rightmost
14347     argument being the least-significant bit; each bit is 0 if the corresponding
14348     expression is included in the grouping criteria of the grouping set generating
14349     the result row, and 1 if it is not.  For example:
14350 <screen>
14351 <prompt>=&gt;</> <userinput>SELECT * FROM items_sold;</>
14352  make  | model | sales
14353 -------+-------+-------
14354  Foo   | GT    |  10
14355  Foo   | Tour  |  20
14356  Bar   | City  |  15
14357  Bar   | Sport |  5
14358 (4 rows)
14359
14360 <prompt>=&gt;</> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);</>
14361  make  | model | grouping | sum
14362 -------+-------+----------+-----
14363  Foo   | GT    |        0 | 10
14364  Foo   | Tour  |        0 | 20
14365  Bar   | City  |        0 | 15
14366  Bar   | Sport |        0 | 5
14367  Foo   |       |        1 | 30
14368  Bar   |       |        1 | 20
14369        |       |        3 | 50
14370 (7 rows)
14371 </screen>
14372    </para>
14373
14374  </sect1>
14375
14376  <sect1 id="functions-window">
14377   <title>Window Functions</title>
14378
14379   <indexterm zone="functions-window">
14380    <primary>window function</primary>
14381    <secondary>built-in</secondary>
14382   </indexterm>
14383
14384   <para>
14385    <firstterm>Window functions</firstterm> provide the ability to perform
14386    calculations across sets of rows that are related to the current query
14387    row.  See <xref linkend="tutorial-window"> for an introduction to this
14388    feature, and <xref linkend="syntax-window-functions"> for syntax
14389    details.
14390   </para>
14391
14392   <para>
14393    The built-in window functions are listed in
14394    <xref linkend="functions-window-table">.  Note that these functions
14395    <emphasis>must</> be invoked using window function syntax; that is an
14396    <literal>OVER</> clause is required.
14397   </para>
14398
14399   <para>
14400    In addition to these functions, any built-in or user-defined normal
14401    aggregate function (but not ordered-set or hypothetical-set aggregates)
14402    can be used as a window function; see
14403    <xref linkend="functions-aggregate"> for a list of the built-in aggregates.
14404    Aggregate functions act as window functions only when an <literal>OVER</>
14405    clause follows the call; otherwise they act as regular aggregates.
14406   </para>
14407
14408   <table id="functions-window-table">
14409    <title>General-Purpose Window Functions</title>
14410
14411    <tgroup cols="3">
14412     <thead>
14413      <row>
14414       <entry>Function</entry>
14415       <entry>Return Type</entry>
14416       <entry>Description</entry>
14417      </row>
14418     </thead>
14419
14420     <tbody>
14421      <row>
14422       <entry>
14423        <indexterm>
14424         <primary>row_number</primary>
14425        </indexterm>
14426        <function>row_number()</function>
14427       </entry>
14428       <entry>
14429        <type>bigint</type>
14430       </entry>
14431       <entry>number of the current row within its partition, counting from 1</entry>
14432      </row>
14433
14434      <row>
14435       <entry>
14436        <indexterm>
14437         <primary>rank</primary>
14438        </indexterm>
14439        <function>rank()</function>
14440       </entry>
14441       <entry>
14442        <type>bigint</type>
14443       </entry>
14444       <entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
14445      </row>
14446
14447      <row>
14448       <entry>
14449        <indexterm>
14450         <primary>dense_rank</primary>
14451        </indexterm>
14452        <function>dense_rank()</function>
14453       </entry>
14454       <entry>
14455        <type>bigint</type>
14456       </entry>
14457       <entry>rank of the current row without gaps; this function counts peer groups</entry>
14458      </row>
14459
14460      <row>
14461       <entry>
14462        <indexterm>
14463         <primary>percent_rank</primary>
14464        </indexterm>
14465        <function>percent_rank()</function>
14466       </entry>
14467       <entry>
14468        <type>double precision</type>
14469       </entry>
14470       <entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
14471      </row>
14472
14473      <row>
14474       <entry>
14475        <indexterm>
14476         <primary>cume_dist</primary>
14477        </indexterm>
14478        <function>cume_dist()</function>
14479       </entry>
14480       <entry>
14481        <type>double precision</type>
14482       </entry>
14483       <entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
14484      </row>
14485
14486      <row>
14487       <entry>
14488        <indexterm>
14489         <primary>ntile</primary>
14490        </indexterm>
14491        <function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</>)</function>
14492       </entry>
14493       <entry>
14494        <type>integer</type>
14495       </entry>
14496       <entry>integer ranging from 1 to the argument value, dividing the
14497        partition as equally as possible</entry>
14498      </row>
14499
14500      <row>
14501       <entry>
14502        <indexterm>
14503         <primary>lag</primary>
14504        </indexterm>
14505        <function>
14506          lag(<replaceable class="parameter">value</replaceable> <type>anyelement</>
14507              [, <replaceable class="parameter">offset</replaceable> <type>integer</>
14508              [, <replaceable class="parameter">default</replaceable> <type>anyelement</> ]])
14509        </function>
14510       </entry>
14511       <entry>
14512        <type>same type as <replaceable class="parameter">value</replaceable></type>
14513       </entry>
14514       <entry>
14515        returns <replaceable class="parameter">value</replaceable> evaluated at
14516        the row that is <replaceable class="parameter">offset</replaceable>
14517        rows before the current row within the partition; if there is no such
14518        row, instead return <replaceable class="parameter">default</replaceable>
14519        (which must be of the same type as
14520        <replaceable class="parameter">value</replaceable>).
14521        Both <replaceable class="parameter">offset</replaceable> and
14522        <replaceable class="parameter">default</replaceable> are evaluated
14523        with respect to the current row.  If omitted,
14524        <replaceable class="parameter">offset</replaceable> defaults to 1 and
14525        <replaceable class="parameter">default</replaceable> to null
14526       </entry>
14527      </row>
14528
14529      <row>
14530       <entry>
14531        <indexterm>
14532         <primary>lead</primary>
14533        </indexterm>
14534        <function>
14535          lead(<replaceable class="parameter">value</replaceable> <type>anyelement</>
14536               [, <replaceable class="parameter">offset</replaceable> <type>integer</>
14537               [, <replaceable class="parameter">default</replaceable> <type>anyelement</> ]])
14538        </function>
14539       </entry>
14540       <entry>
14541        <type>same type as <replaceable class="parameter">value</replaceable></type>
14542       </entry>
14543       <entry>
14544        returns <replaceable class="parameter">value</replaceable> evaluated at
14545        the row that is <replaceable class="parameter">offset</replaceable>
14546        rows after the current row within the partition; if there is no such
14547        row, instead return <replaceable class="parameter">default</replaceable>
14548        (which must be of the same type as
14549        <replaceable class="parameter">value</replaceable>).
14550        Both <replaceable class="parameter">offset</replaceable> and
14551        <replaceable class="parameter">default</replaceable> are evaluated
14552        with respect to the current row.  If omitted,
14553        <replaceable class="parameter">offset</replaceable> defaults to 1 and
14554        <replaceable class="parameter">default</replaceable> to null
14555       </entry>
14556      </row>
14557
14558      <row>
14559       <entry>
14560        <indexterm>
14561         <primary>first_value</primary>
14562        </indexterm>
14563        <function>first_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
14564       </entry>
14565       <entry>
14566        <type>same type as <replaceable class="parameter">value</replaceable></type>
14567       </entry>
14568       <entry>
14569        returns <replaceable class="parameter">value</replaceable> evaluated
14570        at the row that is the first row of the window frame
14571       </entry>
14572      </row>
14573
14574      <row>
14575       <entry>
14576        <indexterm>
14577         <primary>last_value</primary>
14578        </indexterm>
14579        <function>last_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
14580       </entry>
14581       <entry>
14582        <type>same type as <replaceable class="parameter">value</replaceable></type>
14583       </entry>
14584       <entry>
14585        returns <replaceable class="parameter">value</replaceable> evaluated
14586        at the row that is the last row of the window frame
14587       </entry>
14588      </row>
14589
14590      <row>
14591       <entry>
14592        <indexterm>
14593         <primary>nth_value</primary>
14594        </indexterm>
14595        <function>
14596          nth_value(<replaceable class="parameter">value</replaceable> <type>any</>, <replaceable class="parameter">nth</replaceable> <type>integer</>)
14597        </function>
14598       </entry>
14599       <entry>
14600        <type>same type as <replaceable class="parameter">value</replaceable></type>
14601       </entry>
14602       <entry>
14603        returns <replaceable class="parameter">value</replaceable> evaluated
14604        at the row that is the <replaceable class="parameter">nth</replaceable>
14605        row of the window frame (counting from 1); null if no such row
14606       </entry>
14607      </row>
14608     </tbody>
14609    </tgroup>
14610   </table>
14611
14612   <para>
14613    All of the functions listed in
14614    <xref linkend="functions-window-table"> depend on the sort ordering
14615    specified by the <literal>ORDER BY</> clause of the associated window
14616    definition.  Rows that are not distinct in the <literal>ORDER BY</>
14617    ordering are said to be <firstterm>peers</>; the four ranking functions
14618    are defined so that they give the same answer for any two peer rows.
14619   </para>
14620
14621   <para>
14622    Note that <function>first_value</>, <function>last_value</>, and
14623    <function>nth_value</> consider only the rows within the <quote>window
14624    frame</>, which by default contains the rows from the start of the
14625    partition through the last peer of the current row.  This is
14626    likely to give unhelpful results for <function>last_value</> and
14627    sometimes also <function>nth_value</>.  You can redefine the frame by
14628    adding a suitable frame specification (<literal>RANGE</> or
14629    <literal>ROWS</>) to the <literal>OVER</> clause.
14630    See <xref linkend="syntax-window-functions"> for more information
14631    about frame specifications.
14632   </para>
14633
14634   <para>
14635    When an aggregate function is used as a window function, it aggregates
14636    over the rows within the current row's window frame.
14637    An aggregate used with <literal>ORDER BY</> and the default window frame
14638    definition produces a <quote>running sum</> type of behavior, which may or
14639    may not be what's wanted.  To obtain
14640    aggregation over the whole partition, omit <literal>ORDER BY</> or use
14641    <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
14642    Other frame specifications can be used to obtain other effects.
14643   </para>
14644
14645   <note>
14646    <para>
14647     The SQL standard defines a <literal>RESPECT NULLS</> or
14648     <literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
14649     <function>first_value</>, <function>last_value</>, and
14650     <function>nth_value</>.  This is not implemented in
14651     <productname>PostgreSQL</productname>: the behavior is always the
14652     same as the standard's default, namely <literal>RESPECT NULLS</>.
14653     Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
14654     option for <function>nth_value</> is not implemented: only the
14655     default <literal>FROM FIRST</> behavior is supported.  (You can achieve
14656     the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
14657     ordering.)
14658    </para>
14659   </note>
14660
14661  </sect1>
14662
14663  <sect1 id="functions-subquery">
14664   <title>Subquery Expressions</title>
14665
14666   <indexterm>
14667    <primary>EXISTS</primary>
14668   </indexterm>
14669
14670   <indexterm>
14671    <primary>IN</primary>
14672   </indexterm>
14673
14674   <indexterm>
14675    <primary>NOT IN</primary>
14676   </indexterm>
14677
14678   <indexterm>
14679    <primary>ANY</primary>
14680   </indexterm>
14681
14682   <indexterm>
14683    <primary>ALL</primary>
14684   </indexterm>
14685
14686   <indexterm>
14687    <primary>SOME</primary>
14688   </indexterm>
14689
14690   <indexterm>
14691    <primary>subquery</primary>
14692   </indexterm>
14693
14694   <para>
14695    This section describes the <acronym>SQL</acronym>-compliant subquery
14696    expressions available in <productname>PostgreSQL</productname>.
14697    All of the expression forms documented in this section return
14698    Boolean (true/false) results.
14699   </para>
14700
14701   <sect2 id="functions-subquery-exists">
14702    <title><literal>EXISTS</literal></title>
14703
14704 <synopsis>
14705 EXISTS (<replaceable>subquery</replaceable>)
14706 </synopsis>
14707
14708   <para>
14709    The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
14710    or <firstterm>subquery</firstterm>.  The
14711    subquery is evaluated to determine whether it returns any rows.
14712    If it returns at least one row, the result of <token>EXISTS</token> is
14713    <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
14714    is <quote>false</>.
14715   </para>
14716
14717   <para>
14718    The subquery can refer to variables from the surrounding query,
14719    which will act as constants during any one evaluation of the subquery.
14720   </para>
14721
14722   <para>
14723    The subquery will generally only be executed long enough to determine
14724    whether at least one row is returned, not all the way to completion.
14725    It is unwise to write a subquery that has side effects (such as
14726    calling sequence functions); whether the side effects occur
14727    might be unpredictable.
14728   </para>
14729
14730   <para>
14731    Since the result depends only on whether any rows are returned,
14732    and not on the contents of those rows, the output list of the
14733    subquery is normally unimportant.  A common coding convention is
14734    to write all <literal>EXISTS</> tests in the form
14735    <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
14736    this rule however, such as subqueries that use <token>INTERSECT</token>.
14737   </para>
14738
14739   <para>
14740    This simple example is like an inner join on <literal>col2</>, but
14741    it produces at most one output row for each <literal>tab1</> row,
14742    even if there are several matching <literal>tab2</> rows:
14743 <screen>
14744 SELECT col1
14745 FROM tab1
14746 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
14747 </screen>
14748   </para>
14749   </sect2>
14750
14751   <sect2 id="functions-subquery-in">
14752    <title><literal>IN</literal></title>
14753
14754 <synopsis>
14755 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
14756 </synopsis>
14757
14758   <para>
14759    The right-hand side is a parenthesized
14760    subquery, which must return exactly one column.  The left-hand expression
14761    is evaluated and compared to each row of the subquery result.
14762    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
14763    The result is <quote>false</> if no equal row is found (including the
14764    case where the subquery returns no rows).
14765   </para>
14766
14767   <para>
14768    Note that if the left-hand expression yields null, or if there are
14769    no equal right-hand values and at least one right-hand row yields
14770    null, the result of the <token>IN</token> construct will be null, not false.
14771    This is in accordance with SQL's normal rules for Boolean combinations
14772    of null values.
14773   </para>
14774
14775   <para>
14776    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
14777    be evaluated completely.
14778   </para>
14779
14780 <synopsis>
14781 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
14782 </synopsis>
14783
14784   <para>
14785    The left-hand side of this form of <token>IN</token> is a row constructor,
14786    as described in <xref linkend="sql-syntax-row-constructors">.
14787    The right-hand side is a parenthesized
14788    subquery, which must return exactly as many columns as there are
14789    expressions in the left-hand row.  The left-hand expressions are
14790    evaluated and compared row-wise to each row of the subquery result.
14791    The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
14792    The result is <quote>false</> if no equal row is found (including the
14793    case where the subquery returns no rows).
14794   </para>
14795
14796   <para>
14797    As usual, null values in the rows are combined per
14798    the normal rules of SQL Boolean expressions.  Two rows are considered
14799    equal if all their corresponding members are non-null and equal; the rows
14800    are unequal if any corresponding members are non-null and unequal;
14801    otherwise the result of that row comparison is unknown (null).
14802    If all the per-row results are either unequal or null, with at least one
14803    null, then the result of <token>IN</token> is null.
14804   </para>
14805   </sect2>
14806
14807   <sect2 id="functions-subquery-notin">
14808    <title><literal>NOT IN</literal></title>
14809
14810 <synopsis>
14811 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
14812 </synopsis>
14813
14814   <para>
14815    The right-hand side is a parenthesized
14816    subquery, which must return exactly one column.  The left-hand expression
14817    is evaluated and compared to each row of the subquery result.
14818    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
14819    are found (including the case where the subquery returns no rows).
14820    The result is <quote>false</> if any equal row is found.
14821   </para>
14822
14823   <para>
14824    Note that if the left-hand expression yields null, or if there are
14825    no equal right-hand values and at least one right-hand row yields
14826    null, the result of the <token>NOT IN</token> construct will be null, not true.
14827    This is in accordance with SQL's normal rules for Boolean combinations
14828    of null values.
14829   </para>
14830
14831   <para>
14832    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
14833    be evaluated completely.
14834   </para>
14835
14836 <synopsis>
14837 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
14838 </synopsis>
14839
14840   <para>
14841    The left-hand side of this form of <token>NOT IN</token> is a row constructor,
14842    as described in <xref linkend="sql-syntax-row-constructors">.
14843    The right-hand side is a parenthesized
14844    subquery, which must return exactly as many columns as there are
14845    expressions in the left-hand row.  The left-hand expressions are
14846    evaluated and compared row-wise to each row of the subquery result.
14847    The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
14848    are found (including the case where the subquery returns no rows).
14849    The result is <quote>false</> if any equal row is found.
14850   </para>
14851
14852   <para>
14853    As usual, null values in the rows are combined per
14854    the normal rules of SQL Boolean expressions.  Two rows are considered
14855    equal if all their corresponding members are non-null and equal; the rows
14856    are unequal if any corresponding members are non-null and unequal;
14857    otherwise the result of that row comparison is unknown (null).
14858    If all the per-row results are either unequal or null, with at least one
14859    null, then the result of <token>NOT IN</token> is null.
14860   </para>
14861   </sect2>
14862
14863   <sect2 id="functions-subquery-any-some">
14864    <title><literal>ANY</literal>/<literal>SOME</literal></title>
14865
14866 <synopsis>
14867 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
14868 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
14869 </synopsis>
14870
14871   <para>
14872    The right-hand side is a parenthesized
14873    subquery, which must return exactly one column.  The left-hand expression
14874    is evaluated and compared to each row of the subquery result using the
14875    given <replaceable>operator</replaceable>, which must yield a Boolean
14876    result.
14877    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
14878    The result is <quote>false</> if no true result is found (including the
14879    case where the subquery returns no rows).
14880   </para>
14881
14882   <para>
14883    <token>SOME</token> is a synonym for <token>ANY</token>.
14884    <token>IN</token> is equivalent to <literal>= ANY</literal>.
14885   </para>
14886
14887   <para>
14888    Note that if there are no successes and at least one right-hand row yields
14889    null for the operator's result, the result of the <token>ANY</token> construct
14890    will be null, not false.
14891    This is in accordance with SQL's normal rules for Boolean combinations
14892    of null values.
14893   </para>
14894
14895   <para>
14896    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
14897    be evaluated completely.
14898   </para>
14899
14900 <synopsis>
14901 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
14902 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
14903 </synopsis>
14904
14905   <para>
14906    The left-hand side of this form of <token>ANY</token> is a row constructor,
14907    as described in <xref linkend="sql-syntax-row-constructors">.
14908    The right-hand side is a parenthesized
14909    subquery, which must return exactly as many columns as there are
14910    expressions in the left-hand row.  The left-hand expressions are
14911    evaluated and compared row-wise to each row of the subquery result,
14912    using the given <replaceable>operator</replaceable>.
14913    The result of <token>ANY</token> is <quote>true</> if the comparison
14914    returns true for any subquery row.
14915    The result is <quote>false</> if the comparison returns false for every
14916    subquery row (including the case where the subquery returns no
14917    rows).
14918    The result is NULL if the comparison does not return true for any row,
14919    and it returns NULL for at least one row.
14920   </para>
14921
14922   <para>
14923    See <xref linkend="row-wise-comparison"> for details about the meaning
14924    of a row constructor comparison.
14925   </para>
14926   </sect2>
14927
14928   <sect2 id="functions-subquery-all">
14929    <title><literal>ALL</literal></title>
14930
14931 <synopsis>
14932 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
14933 </synopsis>
14934
14935   <para>
14936    The right-hand side is a parenthesized
14937    subquery, which must return exactly one column.  The left-hand expression
14938    is evaluated and compared to each row of the subquery result using the
14939    given <replaceable>operator</replaceable>, which must yield a Boolean
14940    result.
14941    The result of <token>ALL</token> is <quote>true</> if all rows yield true
14942    (including the case where the subquery returns no rows).
14943    The result is <quote>false</> if any false result is found.
14944    The result is NULL if the comparison does not return false for any row,
14945    and it returns NULL for at least one row.
14946   </para>
14947
14948   <para>
14949    <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
14950   </para>
14951
14952   <para>
14953    As with <token>EXISTS</token>, it's unwise to assume that the subquery will
14954    be evaluated completely.
14955   </para>
14956
14957 <synopsis>
14958 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
14959 </synopsis>
14960
14961   <para>
14962    The left-hand side of this form of <token>ALL</token> is a row constructor,
14963    as described in <xref linkend="sql-syntax-row-constructors">.
14964    The right-hand side is a parenthesized
14965    subquery, which must return exactly as many columns as there are
14966    expressions in the left-hand row.  The left-hand expressions are
14967    evaluated and compared row-wise to each row of the subquery result,
14968    using the given <replaceable>operator</replaceable>.
14969    The result of <token>ALL</token> is <quote>true</> if the comparison
14970    returns true for all subquery rows (including the
14971    case where the subquery returns no rows).
14972    The result is <quote>false</> if the comparison returns false for any
14973    subquery row.
14974    The result is NULL if the comparison does not return false for any
14975    subquery row, and it returns NULL for at least one row.
14976   </para>
14977
14978   <para>
14979    See <xref linkend="row-wise-comparison"> for details about the meaning
14980    of a row constructor comparison.
14981   </para>
14982   </sect2>
14983
14984   <sect2>
14985    <title>Single-row Comparison</title>
14986
14987    <indexterm zone="functions-subquery">
14988     <primary>comparison</primary>
14989     <secondary>subquery result row</secondary>
14990    </indexterm>
14991
14992 <synopsis>
14993 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
14994 </synopsis>
14995
14996   <para>
14997    The left-hand side is a row constructor,
14998    as described in <xref linkend="sql-syntax-row-constructors">.
14999    The right-hand side is a parenthesized subquery, which must return exactly
15000    as many columns as there are expressions in the left-hand row. Furthermore,
15001    the subquery cannot return more than one row.  (If it returns zero rows,
15002    the result is taken to be null.)  The left-hand side is evaluated and
15003    compared row-wise to the single subquery result row.
15004   </para>
15005
15006   <para>
15007    See <xref linkend="row-wise-comparison"> for details about the meaning
15008    of a row constructor comparison.
15009   </para>
15010   </sect2>
15011  </sect1>
15012
15013
15014  <sect1 id="functions-comparisons">
15015   <title>Row and Array Comparisons</title>
15016
15017   <indexterm>
15018    <primary>IN</primary>
15019   </indexterm>
15020
15021   <indexterm>
15022    <primary>NOT IN</primary>
15023   </indexterm>
15024
15025   <indexterm>
15026    <primary>ANY</primary>
15027   </indexterm>
15028
15029   <indexterm>
15030    <primary>ALL</primary>
15031   </indexterm>
15032
15033   <indexterm>
15034    <primary>SOME</primary>
15035   </indexterm>
15036
15037   <indexterm>
15038    <primary>composite type</primary>
15039    <secondary>comparison</secondary>
15040   </indexterm>
15041
15042   <indexterm>
15043    <primary>row-wise comparison</primary>
15044   </indexterm>
15045
15046   <indexterm>
15047    <primary>comparison</primary>
15048    <secondary>composite type</secondary>
15049   </indexterm>
15050
15051   <indexterm>
15052    <primary>comparison</primary>
15053    <secondary>row constructor</secondary>
15054   </indexterm>
15055
15056   <indexterm>
15057    <primary>IS DISTINCT FROM</primary>
15058   </indexterm>
15059
15060   <indexterm>
15061    <primary>IS NOT DISTINCT FROM</primary>
15062   </indexterm>
15063
15064   <para>
15065    This section describes several specialized constructs for making
15066    multiple comparisons between groups of values.  These forms are
15067    syntactically related to the subquery forms of the previous section,
15068    but do not involve subqueries.
15069    The forms involving array subexpressions are
15070    <productname>PostgreSQL</productname> extensions; the rest are
15071    <acronym>SQL</acronym>-compliant.
15072    All of the expression forms documented in this section return
15073    Boolean (true/false) results.
15074   </para>
15075
15076   <sect2 id="functions-comparisons-in-scalar">
15077    <title><literal>IN</literal></title>
15078
15079 <synopsis>
15080 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
15081 </synopsis>
15082
15083   <para>
15084    The right-hand side is a parenthesized list
15085    of scalar expressions.  The result is <quote>true</> if the left-hand expression's
15086    result is equal to any of the right-hand expressions.  This is a shorthand
15087    notation for
15088
15089 <synopsis>
15090 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
15091 OR
15092 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
15093 OR
15094 ...
15095 </synopsis>
15096   </para>
15097
15098   <para>
15099    Note that if the left-hand expression yields null, or if there are
15100    no equal right-hand values and at least one right-hand expression yields
15101    null, the result of the <token>IN</token> construct will be null, not false.
15102    This is in accordance with SQL's normal rules for Boolean combinations
15103    of null values.
15104   </para>
15105   </sect2>
15106
15107   <sect2>
15108    <title><literal>NOT IN</literal></title>
15109
15110 <synopsis>
15111 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
15112 </synopsis>
15113
15114   <para>
15115    The right-hand side is a parenthesized list
15116    of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
15117    result is unequal to all of the right-hand expressions.  This is a shorthand
15118    notation for
15119
15120 <synopsis>
15121 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
15122 AND
15123 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
15124 AND
15125 ...
15126 </synopsis>
15127   </para>
15128
15129   <para>
15130    Note that if the left-hand expression yields null, or if there are
15131    no equal right-hand values and at least one right-hand expression yields
15132    null, the result of the <token>NOT IN</token> construct will be null, not true
15133    as one might naively expect.
15134    This is in accordance with SQL's normal rules for Boolean combinations
15135    of null values.
15136   </para>
15137
15138   <tip>
15139   <para>
15140    <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
15141    cases.  However, null values are much more likely to trip up the novice when
15142    working with <token>NOT IN</token> than when working with <token>IN</token>.
15143    It is best to express your condition positively if possible.
15144   </para>
15145   </tip>
15146   </sect2>
15147
15148   <sect2>
15149    <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
15150
15151 <synopsis>
15152 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
15153 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
15154 </synopsis>
15155
15156   <para>
15157    The right-hand side is a parenthesized expression, which must yield an
15158    array value.
15159    The left-hand expression
15160    is evaluated and compared to each element of the array using the
15161    given <replaceable>operator</replaceable>, which must yield a Boolean
15162    result.
15163    The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
15164    The result is <quote>false</> if no true result is found (including the
15165    case where the array has zero elements).
15166   </para>
15167
15168   <para>
15169    If the array expression yields a null array, the result of
15170    <token>ANY</token> will be null.  If the left-hand expression yields null,
15171    the result of <token>ANY</token> is ordinarily null (though a non-strict
15172    comparison operator could possibly yield a different result).
15173    Also, if the right-hand array contains any null elements and no true
15174    comparison result is obtained, the result of <token>ANY</token>
15175    will be null, not false (again, assuming a strict comparison operator).
15176    This is in accordance with SQL's normal rules for Boolean combinations
15177    of null values.
15178   </para>
15179
15180   <para>
15181    <token>SOME</token> is a synonym for <token>ANY</token>.
15182   </para>
15183   </sect2>
15184
15185   <sect2>
15186    <title><literal>ALL</literal> (array)</title>
15187
15188 <synopsis>
15189 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
15190 </synopsis>
15191
15192   <para>
15193    The right-hand side is a parenthesized expression, which must yield an
15194    array value.
15195    The left-hand expression
15196    is evaluated and compared to each element of the array using the
15197    given <replaceable>operator</replaceable>, which must yield a Boolean
15198    result.
15199    The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
15200    (including the case where the array has zero elements).
15201    The result is <quote>false</> if any false result is found.
15202   </para>
15203
15204   <para>
15205    If the array expression yields a null array, the result of
15206    <token>ALL</token> will be null.  If the left-hand expression yields null,
15207    the result of <token>ALL</token> is ordinarily null (though a non-strict
15208    comparison operator could possibly yield a different result).
15209    Also, if the right-hand array contains any null elements and no false
15210    comparison result is obtained, the result of <token>ALL</token>
15211    will be null, not true (again, assuming a strict comparison operator).
15212    This is in accordance with SQL's normal rules for Boolean combinations
15213    of null values.
15214   </para>
15215   </sect2>
15216
15217   <sect2 id="row-wise-comparison">
15218    <title>Row Constructor Comparison</title>
15219
15220 <synopsis>
15221 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
15222 </synopsis>
15223
15224   <para>
15225    Each side is a row constructor,
15226    as described in <xref linkend="sql-syntax-row-constructors">.
15227    The two row values must have the same number of fields.
15228    Each side is evaluated and they are compared row-wise.  Row constructor
15229    comparisons are allowed when the <replaceable>operator</replaceable> is
15230    <literal>=</>,
15231    <literal>&lt;&gt;</>,
15232    <literal>&lt;</>,
15233    <literal>&lt;=</>,
15234    <literal>&gt;</> or
15235    <literal>&gt;=</>.
15236    Every row element must be of a type which has a default B-tree operator
15237    class or the attempted comparison may generate an error.
15238   </para>
15239
15240   <note>
15241    <para>
15242     Errors related to the number or types of elements might not occur if
15243     the comparison is resolved using earlier columns.
15244    </para>
15245   </note>
15246
15247   <para>
15248    The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
15249    from the others.  Two rows are considered
15250    equal if all their corresponding members are non-null and equal; the rows
15251    are unequal if any corresponding members are non-null and unequal;
15252    otherwise the result of the row comparison is unknown (null).
15253   </para>
15254
15255   <para>
15256    For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
15257    <literal>&gt;=</> cases, the row elements are compared left-to-right,
15258    stopping as soon as an unequal or null pair of elements is found.
15259    If either of this pair of elements is null, the result of the
15260    row comparison is unknown (null); otherwise comparison of this pair
15261    of elements determines the result.  For example,
15262    <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
15263    yields true, not null, because the third pair of elements are not
15264    considered.
15265   </para>
15266
15267   <note>
15268    <para>
15269     Prior to <productname>PostgreSQL</productname> 8.2, the
15270     <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
15271     cases were not handled per SQL specification.  A comparison like
15272     <literal>ROW(a,b) &lt; ROW(c,d)</>
15273     was implemented as
15274     <literal>a &lt; c AND b &lt; d</>
15275     whereas the correct behavior is equivalent to
15276     <literal>a &lt; c OR (a = c AND b &lt; d)</>.
15277    </para>
15278   </note>
15279
15280 <synopsis>
15281 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
15282 </synopsis>
15283
15284   <para>
15285    This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
15286    but it does not yield null for null inputs.  Instead, any null value is
15287    considered unequal to (distinct from) any non-null value, and any two
15288    nulls are considered equal (not distinct).  Thus the result will
15289    either be true or false, never null.
15290   </para>
15291
15292 <synopsis>
15293 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
15294 </synopsis>
15295
15296   <para>
15297    This construct is similar to a <literal>=</literal> row comparison,
15298    but it does not yield null for null inputs.  Instead, any null value is
15299    considered unequal to (distinct from) any non-null value, and any two
15300    nulls are considered equal (not distinct).  Thus the result will always
15301    be either true or false, never null.
15302   </para>
15303
15304   </sect2>
15305
15306   <sect2 id="composite-type-comparison">
15307    <title>Composite Type Comparison</title>
15308
15309 <synopsis>
15310 <replaceable>record</replaceable> <replaceable>operator</replaceable> <replaceable>record</replaceable>
15311 </synopsis>
15312
15313   <para>
15314    The SQL specification requires row-wise comparison to return NULL if the
15315    result depends on comparing two NULL values or a NULL and a non-NULL.
15316    <productname>PostgreSQL</productname> does this only when comparing the
15317    results of two row constructors (as in
15318    <xref linkend="row-wise-comparison">) or comparing a row constructor
15319    to the output of a subquery (as in <xref linkend="functions-subquery">).
15320    In other contexts where two composite-type values are compared, two
15321    NULL field values are considered equal, and a NULL is considered larger
15322    than a non-NULL.  This is necessary in order to have consistent sorting
15323    and indexing behavior for composite types.
15324   </para>
15325
15326   <para>
15327    Each side is evaluated and they are compared row-wise.  Composite type
15328    comparisons are allowed when the <replaceable>operator</replaceable> is
15329    <literal>=</>,
15330    <literal>&lt;&gt;</>,
15331    <literal>&lt;</>,
15332    <literal>&lt;=</>,
15333    <literal>&gt;</> or
15334    <literal>&gt;=</>,
15335    or has semantics similar to one of these.  (To be specific, an operator
15336    can be a row comparison operator if it is a member of a B-tree operator
15337    class, or is the negator of the <literal>=</> member of a B-tree operator
15338    class.)  The default behavior of the above operators is the same as for
15339    <literal>IS [ NOT ] DISTINCT FROM</literal> for row constructors (see
15340    <xref linkend="row-wise-comparison">).
15341   </para>
15342
15343   <para>
15344    To support matching of rows which include elements without a default
15345    B-tree operator class, the following operators are defined for composite
15346    type comparison:
15347    <literal>*=</>,
15348    <literal>*&lt;&gt;</>,
15349    <literal>*&lt;</>,
15350    <literal>*&lt;=</>,
15351    <literal>*&gt;</>, and
15352    <literal>*&gt;=</>.
15353    These operators compare the internal binary representation of the two
15354    rows.  Two rows might have a different binary representation even
15355    though comparisons of the two rows with the equality operator is true.
15356    The ordering of rows under these comparison operators is deterministic
15357    but not otherwise meaningful.  These operators are used internally for
15358    materialized views and might be useful for other specialized purposes
15359    such as replication but are not intended to be generally useful for
15360    writing queries.
15361   </para>
15362   </sect2>
15363  </sect1>
15364
15365  <sect1 id="functions-srf">
15366   <title>Set Returning Functions</title>
15367
15368   <indexterm zone="functions-srf">
15369    <primary>set returning functions</primary>
15370    <secondary>functions</secondary>
15371   </indexterm>
15372
15373   <indexterm>
15374    <primary>generate_series</primary>
15375   </indexterm>
15376
15377   <para>
15378    This section describes functions that possibly return more than one row.
15379    The most widely used functions in this class are series generating
15380    functions, as detailed in <xref linkend="functions-srf-series"> and
15381    <xref linkend="functions-srf-subscripts">.  Other, more specialized
15382    set-returning functions are described elsewhere in this manual.
15383    See <xref linkend="queries-tablefunctions"> for ways to combine multiple
15384    set-returning functions.
15385   </para>
15386
15387   <table id="functions-srf-series">
15388    <title>Series Generating Functions</title>
15389    <tgroup cols="4">
15390     <thead>
15391      <row>
15392       <entry>Function</entry>
15393       <entry>Argument Type</entry>
15394       <entry>Return Type</entry>
15395       <entry>Description</entry>
15396      </row>
15397     </thead>
15398
15399     <tbody>
15400      <row>
15401       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>)</function></literal></entry>
15402       <entry><type>int</type>, <type>bigint</type> or <type>numeric</type></entry>
15403       <entry><type>setof int</type>, <type>setof bigint</type>, or <type>setof numeric</type> (same as argument type)</entry>
15404       <entry>
15405        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
15406        with a step size of one
15407       </entry>
15408      </row>
15409
15410      <row>
15411       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</function></literal></entry>
15412       <entry><type>int</type>, <type>bigint</type> or <type>numeric</type></entry>
15413       <entry><type>setof int</type>, <type>setof bigint</type> or <type>setof numeric</type> (same as argument type)</entry>
15414       <entry>
15415        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
15416        with a step size of <parameter>step</parameter>
15417       </entry>
15418      </row>
15419
15420      <row>
15421       <entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</function></literal></entry>
15422       <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
15423       <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
15424       <entry>
15425        Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
15426        with a step size of <parameter>step</parameter>
15427       </entry>
15428      </row>
15429
15430     </tbody>
15431    </tgroup>
15432   </table>
15433
15434   <para>
15435    When <parameter>step</parameter> is positive, zero rows are returned if
15436    <parameter>start</parameter> is greater than <parameter>stop</parameter>.
15437    Conversely, when <parameter>step</parameter> is negative, zero rows are
15438    returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
15439    Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
15440    for <parameter>step</parameter> to be zero. Some examples follow:
15441 <programlisting>
15442 SELECT * FROM generate_series(2,4);
15443  generate_series
15444 -----------------
15445                2
15446                3
15447                4
15448 (3 rows)
15449
15450 SELECT * FROM generate_series(5,1,-2);
15451  generate_series
15452 -----------------
15453                5
15454                3
15455                1
15456 (3 rows)
15457
15458 SELECT * FROM generate_series(4,3);
15459  generate_series
15460 -----------------
15461 (0 rows)
15462
15463 SELECT generate_series(1.1, 4, 1.3);
15464  generate_series 
15465 -----------------
15466              1.1
15467              2.4
15468              3.7
15469 (3 rows)
15470
15471 -- this example relies on the date-plus-integer operator
15472 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
15473    dates
15474 ------------
15475  2004-02-05
15476  2004-02-12
15477  2004-02-19
15478 (3 rows)
15479
15480 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
15481                               '2008-03-04 12:00', '10 hours');
15482    generate_series   
15483 ---------------------
15484  2008-03-01 00:00:00
15485  2008-03-01 10:00:00
15486  2008-03-01 20:00:00
15487  2008-03-02 06:00:00
15488  2008-03-02 16:00:00
15489  2008-03-03 02:00:00
15490  2008-03-03 12:00:00
15491  2008-03-03 22:00:00
15492  2008-03-04 08:00:00
15493 (9 rows)
15494 </programlisting>
15495   </para>
15496
15497   <table id="functions-srf-subscripts">
15498    <title>Subscript Generating Functions</title>
15499    <tgroup cols="3">
15500     <thead>
15501      <row>
15502       <entry>Function</entry>
15503       <entry>Return Type</entry>
15504       <entry>Description</entry>
15505      </row>
15506     </thead>
15507
15508     <tbody>
15509      <row>
15510       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</function></literal></entry>
15511       <entry><type>setof int</type></entry>
15512       <entry>
15513        Generate a series comprising the given array's subscripts.
15514       </entry>
15515      </row>
15516
15517      <row>
15518       <entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</function></literal></entry>
15519       <entry><type>setof int</type></entry>
15520       <entry>
15521        Generate a series comprising the given array's subscripts. When
15522        <parameter>reverse</parameter> is true, the series is returned in
15523        reverse order.
15524       </entry>
15525      </row>
15526
15527     </tbody>
15528    </tgroup>
15529   </table>
15530
15531   <indexterm>
15532    <primary>generate_subscripts</primary>
15533   </indexterm>
15534
15535   <para>
15536    <function>generate_subscripts</> is a convenience function that generates
15537    the set of valid subscripts for the specified dimension of the given
15538    array.
15539    Zero rows are returned for arrays that do not have the requested dimension,
15540    or for NULL arrays (but valid subscripts are returned for NULL array
15541    elements).  Some examples follow:
15542 <programlisting>
15543 -- basic usage
15544 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
15545  s 
15546 ---
15547  1
15548  2
15549  3
15550  4
15551 (4 rows)
15552
15553 -- presenting an array, the subscript and the subscripted
15554 -- value requires a subquery
15555 SELECT * FROM arrays;
15556          a          
15557 --------------------
15558  {-1,-2}
15559  {100,200,300}
15560 (2 rows)
15561
15562 SELECT a AS array, s AS subscript, a[s] AS value
15563 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
15564      array     | subscript | value
15565 ---------------+-----------+-------
15566  {-1,-2}       |         1 |    -1
15567  {-1,-2}       |         2 |    -2
15568  {100,200,300} |         1 |   100
15569  {100,200,300} |         2 |   200
15570  {100,200,300} |         3 |   300
15571 (5 rows)
15572
15573 -- unnest a 2D array
15574 CREATE OR REPLACE FUNCTION unnest2(anyarray)
15575 RETURNS SETOF anyelement AS $$
15576 select $1[i][j]
15577    from generate_subscripts($1,1) g1(i),
15578         generate_subscripts($1,2) g2(j);
15579 $$ LANGUAGE sql IMMUTABLE;
15580 CREATE FUNCTION
15581 SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
15582  unnest2 
15583 ---------
15584        1
15585        2
15586        3
15587        4
15588 (4 rows)
15589 </programlisting>
15590   </para>
15591
15592   <indexterm>
15593    <primary>ordinality</primary>
15594   </indexterm>
15595
15596   <para>
15597    When a function in the <literal>FROM</literal> clause is suffixed
15598    by <literal>WITH ORDINALITY</literal>, a <type>bigint</type> column is
15599    appended to the output which starts from 1 and increments by 1 for each row
15600    of the function's output.  This is most useful in the case of set returning
15601    functions such as <function>unnest()</>.
15602
15603 <programlisting>
15604 -- set returning function WITH ORDINALITY
15605 SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
15606        ls        | n
15607 -----------------+----
15608  pg_serial       |  1
15609  pg_twophase     |  2
15610  postmaster.opts |  3
15611  pg_notify       |  4
15612  postgresql.conf |  5
15613  pg_tblspc       |  6
15614  logfile         |  7
15615  base            |  8
15616  postmaster.pid  |  9
15617  pg_ident.conf   | 10
15618  global          | 11
15619  pg_clog         | 12
15620  pg_snapshots    | 13
15621  pg_multixact    | 14
15622  PG_VERSION      | 15
15623  pg_wal          | 16
15624  pg_hba.conf     | 17
15625  pg_stat_tmp     | 18
15626  pg_subtrans     | 19
15627 (19 rows)
15628 </programlisting>
15629   </para>
15630
15631  </sect1>
15632
15633  <sect1 id="functions-info">
15634   <title>System Information Functions</title>
15635
15636   <para>
15637    <xref linkend="functions-info-session-table"> shows several
15638    functions that extract session and system information.
15639   </para>
15640
15641   <para>
15642    In addition to the functions listed in this section, there are a number of
15643    functions related to the statistics system that also provide system
15644    information. See <xref linkend="monitoring-stats-views"> for more
15645    information.
15646   </para>
15647
15648    <table id="functions-info-session-table">
15649     <title>Session Information Functions</title>
15650     <tgroup cols="3">
15651      <thead>
15652       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
15653      </thead>
15654
15655      <tbody>
15656       <row>
15657        <entry><literal><function>current_catalog</function></literal></entry>
15658        <entry><type>name</type></entry>
15659        <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
15660       </row>
15661
15662       <row>
15663        <entry><literal><function>current_database()</function></literal></entry>
15664        <entry><type>name</type></entry>
15665        <entry>name of current database</entry>
15666       </row>
15667
15668       <row>
15669        <entry><literal><function>current_query()</function></literal></entry>
15670        <entry><type>text</type></entry>
15671        <entry>text of the currently executing query, as submitted
15672        by the client (might contain more than one statement)</entry>
15673       </row>
15674
15675       <row>
15676        <entry><literal><function>current_schema</function>[()]</literal></entry>
15677        <entry><type>name</type></entry>
15678        <entry>name of current schema</entry>
15679       </row>
15680
15681       <row>
15682        <entry><literal><function>current_schemas(<type>boolean</type>)</function></literal></entry>
15683        <entry><type>name[]</type></entry>
15684        <entry>names of schemas in search path, optionally including implicit schemas</entry>
15685       </row>
15686
15687       <row>
15688        <entry><literal><function>current_user</function></literal></entry>
15689        <entry><type>name</type></entry>
15690        <entry>user name of current execution context</entry>
15691       </row>
15692
15693       <row>
15694        <entry><literal><function>inet_client_addr()</function></literal></entry>
15695        <entry><type>inet</type></entry>
15696        <entry>address of the remote connection</entry>
15697       </row>
15698
15699       <row>
15700        <entry><literal><function>inet_client_port()</function></literal></entry>
15701        <entry><type>int</type></entry>
15702        <entry>port of the remote connection</entry>
15703       </row>
15704
15705       <row>
15706        <entry><literal><function>inet_server_addr()</function></literal></entry>
15707        <entry><type>inet</type></entry>
15708        <entry>address of the local connection</entry>
15709       </row>
15710
15711       <row>
15712        <entry><literal><function>inet_server_port()</function></literal></entry>
15713        <entry><type>int</type></entry>
15714        <entry>port of the local connection</entry>
15715       </row>
15716
15717       <row>
15718        <!-- See also the entry for this in monitoring.sgml -->
15719        <entry><literal><function>pg_backend_pid()</function></literal></entry>
15720        <entry><type>int</type></entry>
15721        <entry>
15722         Process ID of the server process attached to the current session
15723        </entry>
15724       </row>
15725
15726       <row>
15727        <entry><literal><function>pg_blocking_pids(<type>int</type>)</function></literal></entry>
15728        <entry><type>int[]</type></entry>
15729        <entry>Process ID(s) that are blocking specified server process ID</entry>
15730       </row>
15731
15732       <row>
15733        <entry><literal><function>pg_conf_load_time()</function></literal></entry>
15734        <entry><type>timestamp with time zone</type></entry>
15735        <entry>configuration load time</entry>
15736       </row>
15737
15738       <row>
15739        <entry><literal><function>pg_current_logfile(<optional><type>text</></optional>)</function></literal></entry>
15740        <entry><type>text</type></entry>
15741        <entry>Primary log file name, or log in the requested format,
15742        currently in use by the logging collector</entry>
15743       </row>
15744
15745       <row>
15746        <entry><literal><function>pg_my_temp_schema()</function></literal></entry>
15747        <entry><type>oid</type></entry>
15748        <entry>OID of session's temporary schema, or 0 if none</entry>
15749       </row>
15750
15751       <row>
15752        <entry><literal><function>pg_is_other_temp_schema(<type>oid</type>)</function></literal></entry>
15753        <entry><type>boolean</type></entry>
15754        <entry>is schema another session's temporary schema?</entry>
15755       </row>
15756
15757       <row>
15758        <entry><literal><function>pg_listening_channels()</function></literal></entry>
15759        <entry><type>setof text</type></entry>
15760        <entry>channel names that the session is currently listening on</entry>
15761       </row>
15762
15763       <row>
15764        <entry><literal><function>pg_notification_queue_usage()</function></literal></entry>
15765        <entry><type>double</type></entry>
15766        <entry>fraction of the asynchronous notification queue currently occupied (0-1)</entry>
15767       </row>
15768
15769       <row>
15770        <entry><literal><function>pg_postmaster_start_time()</function></literal></entry>
15771        <entry><type>timestamp with time zone</type></entry>
15772        <entry>server start time</entry>
15773       </row>
15774
15775       <row>
15776        <entry><literal><function>pg_trigger_depth()</function></literal></entry>
15777        <entry><type>int</type></entry>
15778        <entry>current nesting level of <productname>PostgreSQL</> triggers
15779        (0 if not called, directly or indirectly, from inside a trigger)</entry>
15780       </row>
15781
15782       <row>
15783        <entry><literal><function>session_user</function></literal></entry>
15784        <entry><type>name</type></entry>
15785        <entry>session user name</entry>
15786       </row>
15787
15788       <row>
15789        <entry><literal><function>user</function></literal></entry>
15790        <entry><type>name</type></entry>
15791        <entry>equivalent to <function>current_user</function></entry>
15792       </row>
15793
15794       <row>
15795        <entry><literal><function>version()</function></literal></entry>
15796        <entry><type>text</type></entry>
15797        <entry><productname>PostgreSQL</> version information. See also <xref linkend="guc-server-version-num"> for a machine-readable version.</entry>
15798       </row>
15799      </tbody>
15800     </tgroup>
15801    </table>
15802
15803    <note>
15804     <para>
15805      <function>current_catalog</function>, <function>current_schema</function>,
15806      <function>current_user</function>, <function>session_user</function>,
15807      and <function>user</function> have special syntactic status
15808      in <acronym>SQL</acronym>: they must be called without trailing
15809      parentheses.  (In PostgreSQL, parentheses can optionally be used with
15810      <function>current_schema</function>, but not with the others.)
15811     </para>
15812    </note>
15813
15814    <indexterm>
15815     <primary>current_catalog</primary>
15816    </indexterm>
15817
15818    <indexterm>
15819     <primary>current_database</primary>
15820    </indexterm>
15821
15822    <indexterm>
15823     <primary>current_query</primary>
15824    </indexterm>
15825
15826    <indexterm>
15827     <primary>current_schema</primary>
15828    </indexterm>
15829
15830    <indexterm>
15831     <primary>current_schemas</primary>
15832    </indexterm>
15833
15834    <indexterm>
15835     <primary>current_user</primary>
15836    </indexterm>
15837
15838    <indexterm>
15839     <primary>pg_backend_pid</primary>
15840    </indexterm>
15841
15842    <indexterm>
15843     <primary>schema</primary>
15844     <secondary>current</secondary>
15845    </indexterm>
15846
15847    <indexterm>
15848     <primary>search path</primary>
15849     <secondary>current</secondary>
15850    </indexterm>
15851
15852    <indexterm>
15853     <primary>session_user</primary>
15854    </indexterm>
15855
15856    <indexterm>
15857     <primary>user</primary>
15858     <secondary>current</secondary>
15859    </indexterm>
15860
15861    <indexterm>
15862     <primary>user</primary>
15863    </indexterm>
15864
15865    <para>
15866     The <function>session_user</function> is normally the user who initiated
15867     the current database connection; but superusers can change this setting
15868     with <xref linkend="sql-set-session-authorization">.
15869     The <function>current_user</function> is the user identifier
15870     that is applicable for permission checking. Normally it is equal
15871     to the session user, but it can be changed with
15872     <xref linkend="sql-set-role">.
15873     It also changes during the execution of
15874     functions with the attribute <literal>SECURITY DEFINER</literal>.
15875     In Unix parlance, the session user is the <quote>real user</quote> and
15876     the current user is the <quote>effective user</quote>.
15877    </para>
15878
15879    <para>
15880     <function>current_schema</function> returns the name of the schema that is
15881     first in the search path (or a null value if the search path is
15882     empty).  This is the schema that will be used for any tables or
15883     other named objects that are created without specifying a target schema.
15884     <function>current_schemas(boolean)</function> returns an array of the names of all
15885     schemas presently in the search path.  The Boolean option determines whether or not
15886     implicitly included system schemas such as <literal>pg_catalog</> are included in the
15887     returned search path.
15888    </para>
15889
15890    <note>
15891     <para>
15892      The search path can be altered at run time.  The command is:
15893 <programlisting>
15894 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
15895 </programlisting>
15896     </para>
15897    </note>
15898
15899    <indexterm>
15900     <primary>inet_client_addr</primary>
15901    </indexterm>
15902
15903    <indexterm>
15904     <primary>inet_client_port</primary>
15905    </indexterm>
15906
15907    <indexterm>
15908     <primary>inet_server_addr</primary>
15909    </indexterm>
15910
15911    <indexterm>
15912     <primary>inet_server_port</primary>
15913    </indexterm>
15914
15915    <para>
15916      <function>inet_client_addr</function> returns the IP address of the
15917      current client, and <function>inet_client_port</function> returns the
15918      port number.
15919      <function>inet_server_addr</function> returns the IP address on which
15920      the server accepted the current connection, and
15921      <function>inet_server_port</function> returns the port number.
15922      All these functions return NULL if the current connection is via a
15923      Unix-domain socket.
15924    </para>
15925
15926    <indexterm>
15927     <primary>pg_blocking_pids</primary>
15928    </indexterm>
15929
15930    <para>
15931     <function>pg_blocking_pids</function> returns an array of the process IDs
15932     of the sessions that are blocking the server process with the specified
15933     process ID, or an empty array if there is no such server process or it is
15934     not blocked.  One server process blocks another if it either holds a lock
15935     that conflicts with the blocked process's lock request (hard block), or is
15936     waiting for a lock that would conflict with the blocked process's lock
15937     request and is ahead of it in the wait queue (soft block).  When using
15938     parallel queries the result always lists client-visible process IDs (that
15939     is, <function>pg_backend_pid</> results) even if the actual lock is held
15940     or awaited by a child worker process.  As a result of that, there may be
15941     duplicated PIDs in the result.  Also note that when a prepared transaction
15942     holds a conflicting lock, it will be represented by a zero process ID in
15943     the result of this function.
15944     Frequent calls to this function could have some impact on database
15945     performance, because it needs exclusive access to the lock manager's
15946     shared state for a short time.
15947    </para>
15948
15949    <indexterm>
15950     <primary>pg_conf_load_time</primary>
15951    </indexterm>
15952
15953    <para>
15954     <function>pg_conf_load_time</function> returns the
15955     <type>timestamp with time zone</type> when the
15956     server configuration files were last loaded.
15957     (If the current session was alive at the time, this will be the time
15958     when the session itself re-read the configuration files, so the
15959     reading will vary a little in different sessions.  Otherwise it is
15960     the time when the postmaster process re-read the configuration files.)
15961    </para>
15962
15963    <indexterm>
15964     <primary>pg_current_logfile</primary>
15965    </indexterm>
15966
15967    <indexterm>
15968     <primary>Logging</primary>
15969     <secondary>pg_current_logfile function</secondary>
15970    </indexterm>
15971
15972    <indexterm>
15973      <primary>current_logfiles</primary>
15974      <secondary>and the pg_current_logfile function</secondary>
15975    </indexterm>
15976
15977    <indexterm>
15978     <primary>Logging</primary>
15979     <secondary>current_logfiles file and the pg_current_logfile
15980     function</secondary>
15981    </indexterm>
15982
15983    <para>
15984     <function>pg_current_logfile</function> returns, as <type>text</type>,
15985     the path of the log file(s) currently in use by the logging collector.
15986     The path includes the <xref linkend="guc-log-directory"> directory
15987     and the log file name.  Log collection must be enabled or the return value
15988     is <literal>NULL</literal>.  When multiple log files exist, each in a
15989     different format, <function>pg_current_logfile</function> called
15990     without arguments returns the path of the file having the first format
15991     found in the ordered list: <systemitem>stderr</>, <systemitem>csvlog</>.
15992     <literal>NULL</literal> is returned when no log file has any of these
15993     formats.  To request a specific file format supply, as <type>text</type>,
15994     either <systemitem>csvlog</> or <systemitem>stderr</> as the value of the
15995     optional parameter. The return value is <literal>NULL</literal> when the
15996     log format requested is not a configured
15997     <xref linkend="guc-log-destination">.  The
15998     <function>pg_current_logfiles</function> reflects the contents of the
15999     <filename>current_logfiles</> file.
16000    </para>
16001
16002    <indexterm>
16003     <primary>pg_my_temp_schema</primary>
16004    </indexterm>
16005
16006    <indexterm>
16007     <primary>pg_is_other_temp_schema</primary>
16008    </indexterm>
16009
16010    <para>
16011     <function>pg_my_temp_schema</function> returns the OID of the current
16012     session's temporary schema, or zero if it has none (because it has not
16013     created any temporary tables).
16014     <function>pg_is_other_temp_schema</function> returns true if the
16015     given OID is the OID of another session's temporary schema.
16016     (This can be useful, for example, to exclude other sessions' temporary
16017     tables from a catalog display.)
16018    </para>
16019
16020    <indexterm>
16021     <primary>pg_listening_channels</primary>
16022    </indexterm>
16023
16024    <indexterm>
16025     <primary>pg_notification_queue_usage</primary>
16026    </indexterm>
16027
16028    <para>
16029     <function>pg_listening_channels</function> returns a set of names of
16030     asynchronous notification channels that the current session is listening
16031     to.  <function>pg_notification_queue_usage</function> returns the
16032     fraction of the total available space for notifications currently
16033     occupied by notifications that are waiting to be processed, as a
16034     <type>double</type> in the range 0-1.
16035     See <xref linkend="sql-listen"> and <xref linkend="sql-notify">
16036     for more information.
16037    </para>
16038
16039    <indexterm>
16040     <primary>pg_postmaster_start_time</primary>
16041    </indexterm>
16042
16043    <para>
16044     <function>pg_postmaster_start_time</function> returns the
16045     <type>timestamp with time zone</type> when the
16046     server started.
16047    </para>
16048
16049    <indexterm>
16050     <primary>version</primary>
16051    </indexterm>
16052
16053    <para>
16054     <function>version</function> returns a string describing the
16055     <productname>PostgreSQL</productname> server's version. You can also
16056     get this information from <xref linkend="guc-server-version"> or
16057     for a machine-readable version, <xref linkend="guc-server-version-num">.
16058     Software developers should use <literal>server_version_num</literal>
16059     (available since 8.2) or <xref linkend="libpq-pqserverversion"> instead
16060     of parsing the text version.
16061    </para>
16062
16063   <indexterm>
16064    <primary>privilege</primary>
16065    <secondary>querying</secondary>
16066   </indexterm>
16067
16068   <para>
16069    <xref linkend="functions-info-access-table"> lists functions that
16070    allow the user to query object access privileges programmatically.
16071    See <xref linkend="ddl-priv"> for more information about
16072    privileges.
16073   </para>
16074
16075    <table id="functions-info-access-table">
16076     <title>Access Privilege Inquiry Functions</title>
16077     <tgroup cols="3">
16078      <thead>
16079       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
16080      </thead>
16081
16082      <tbody>
16083       <row>
16084        <entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
16085                                   <parameter>table</parameter>,
16086                                   <parameter>privilege</parameter>)</literal>
16087        </entry>
16088        <entry><type>boolean</type></entry>
16089        <entry>does user have privilege for any column of table</entry>
16090       </row>
16091       <row>
16092        <entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
16093                                   <parameter>privilege</parameter>)</literal>
16094        </entry>
16095        <entry><type>boolean</type></entry>
16096        <entry>does current user have privilege for any column of table</entry>
16097       </row>
16098       <row>
16099        <entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
16100                                   <parameter>table</parameter>,
16101                                   <parameter>column</parameter>,
16102                                   <parameter>privilege</parameter>)</literal>
16103        </entry>
16104        <entry><type>boolean</type></entry>
16105        <entry>does user have privilege for column</entry>
16106       </row>
16107       <row>
16108        <entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
16109                                   <parameter>column</parameter>,
16110                                   <parameter>privilege</parameter>)</literal>
16111        </entry>
16112        <entry><type>boolean</type></entry>
16113        <entry>does current user have privilege for column</entry>
16114       </row>
16115       <row>
16116        <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
16117                                   <parameter>database</parameter>,
16118                                   <parameter>privilege</parameter>)</literal>
16119        </entry>
16120        <entry><type>boolean</type></entry>
16121        <entry>does user have privilege for database</entry>
16122       </row>
16123       <row>
16124        <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
16125                                   <parameter>privilege</parameter>)</literal>
16126        </entry>
16127        <entry><type>boolean</type></entry>
16128        <entry>does current user have privilege for database</entry>
16129       </row>
16130       <row>
16131        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
16132                                   <parameter>fdw</parameter>,
16133                                   <parameter>privilege</parameter>)</literal>
16134        </entry>
16135        <entry><type>boolean</type></entry>
16136        <entry>does user have privilege for foreign-data wrapper</entry>
16137       </row>
16138       <row>
16139        <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
16140                                   <parameter>privilege</parameter>)</literal>
16141        </entry>
16142        <entry><type>boolean</type></entry>
16143        <entry>does current user have privilege for foreign-data wrapper</entry>
16144       </row>
16145       <row>
16146        <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
16147                                   <parameter>function</parameter>,
16148                                   <parameter>privilege</parameter>)</literal>
16149        </entry>
16150        <entry><type>boolean</type></entry>
16151        <entry>does user have privilege for function</entry>
16152       </row>
16153       <row>
16154        <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
16155                                   <parameter>privilege</parameter>)</literal>
16156        </entry>
16157        <entry><type>boolean</type></entry>
16158        <entry>does current user have privilege for function</entry>
16159       </row>
16160       <row>
16161        <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
16162                                   <parameter>language</parameter>,
16163                                   <parameter>privilege</parameter>)</literal>
16164        </entry>
16165        <entry><type>boolean</type></entry>
16166        <entry>does user have privilege for language</entry>
16167       </row>
16168       <row>
16169        <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
16170                                   <parameter>privilege</parameter>)</literal>
16171        </entry>
16172        <entry><type>boolean</type></entry>
16173        <entry>does current user have privilege for language</entry>
16174       </row>
16175       <row>
16176        <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
16177                                   <parameter>schema</parameter>,
16178                                   <parameter>privilege</parameter>)</literal>
16179        </entry>
16180        <entry><type>boolean</type></entry>
16181        <entry>does user have privilege for schema</entry>
16182       </row>
16183       <row>
16184        <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
16185                                   <parameter>privilege</parameter>)</literal>
16186        </entry>
16187        <entry><type>boolean</type></entry>
16188        <entry>does current user have privilege for schema</entry>
16189       </row>
16190       <row>
16191        <entry><literal><function>has_sequence_privilege</function>(<parameter>user</parameter>,
16192                                   <parameter>sequence</parameter>,
16193                                   <parameter>privilege</parameter>)</literal>
16194        </entry>
16195        <entry><type>boolean</type></entry>
16196        <entry>does user have privilege for sequence</entry>
16197       </row>
16198       <row>
16199        <entry><literal><function>has_sequence_privilege</function>(<parameter>sequence</parameter>,
16200                                   <parameter>privilege</parameter>)</literal>
16201        </entry>
16202        <entry><type>boolean</type></entry>
16203        <entry>does current user have privilege for sequence</entry>
16204       </row>
16205       <row>
16206        <entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
16207                                   <parameter>server</parameter>,
16208                                   <parameter>privilege</parameter>)</literal>
16209        </entry>
16210        <entry><type>boolean</type></entry>
16211        <entry>does user have privilege for foreign server</entry>
16212       </row>
16213       <row>
16214        <entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
16215                                   <parameter>privilege</parameter>)</literal>
16216        </entry>
16217        <entry><type>boolean</type></entry>
16218        <entry>does current user have privilege for foreign server</entry>
16219       </row>
16220       <row>
16221        <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
16222                                   <parameter>table</parameter>,
16223                                   <parameter>privilege</parameter>)</literal>
16224        </entry>
16225        <entry><type>boolean</type></entry>
16226        <entry>does user have privilege for table</entry>
16227       </row>
16228       <row>
16229        <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
16230                                   <parameter>privilege</parameter>)</literal>
16231        </entry>
16232        <entry><type>boolean</type></entry>
16233        <entry>does current user have privilege for table</entry>
16234       </row>
16235       <row>
16236        <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
16237                                   <parameter>tablespace</parameter>,
16238                                   <parameter>privilege</parameter>)</literal>
16239        </entry>
16240        <entry><type>boolean</type></entry>
16241        <entry>does user have privilege for tablespace</entry>
16242       </row>
16243       <row>
16244        <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
16245                                   <parameter>privilege</parameter>)</literal>
16246        </entry>
16247        <entry><type>boolean</type></entry>
16248        <entry>does current user have privilege for tablespace</entry>
16249       </row>
16250       <row>
16251        <entry><literal><function>has_type_privilege</function>(<parameter>user</parameter>,
16252                                   <parameter>type</parameter>,
16253                                   <parameter>privilege</parameter>)</literal>
16254        </entry>
16255        <entry><type>boolean</type></entry>
16256        <entry>does user have privilege for type</entry>
16257       </row>
16258       <row>
16259        <entry><literal><function>has_type_privilege</function>(<parameter>type</parameter>,
16260                                   <parameter>privilege</parameter>)</literal>
16261        </entry>
16262        <entry><type>boolean</type></entry>
16263        <entry>does current user have privilege for type</entry>
16264       </row>
16265       <row>
16266        <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
16267                                   <parameter>role</parameter>,
16268                                   <parameter>privilege</parameter>)</literal>
16269        </entry>
16270        <entry><type>boolean</type></entry>
16271        <entry>does user have privilege for role</entry>
16272       </row>
16273       <row>
16274        <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
16275                                   <parameter>privilege</parameter>)</literal>
16276        </entry>
16277        <entry><type>boolean</type></entry>
16278        <entry>does current user have privilege for role</entry>
16279       </row>
16280       <row>
16281        <entry><literal><function>row_security_active</function>(<parameter>table</parameter>)</literal>
16282        </entry>
16283        <entry><type>boolean</type></entry>
16284        <entry>does current user have row level security active for table</entry>
16285       </row>
16286      </tbody>
16287     </tgroup>
16288    </table>
16289
16290    <indexterm>
16291     <primary>has_any_column_privilege</primary>
16292    </indexterm>
16293    <indexterm>
16294     <primary>has_column_privilege</primary>
16295    </indexterm>
16296    <indexterm>
16297     <primary>has_database_privilege</primary>
16298    </indexterm>
16299    <indexterm>
16300     <primary>has_function_privilege</primary>
16301    </indexterm>
16302    <indexterm>
16303     <primary>has_foreign_data_wrapper_privilege</primary>
16304    </indexterm>
16305    <indexterm>
16306     <primary>has_language_privilege</primary>
16307    </indexterm>
16308    <indexterm>
16309     <primary>has_schema_privilege</primary>
16310    </indexterm>
16311    <indexterm>
16312     <primary>has_server_privilege</primary>
16313    </indexterm>
16314    <indexterm>
16315     <primary>has_sequence_privilege</primary>
16316    </indexterm>
16317    <indexterm>
16318     <primary>has_table_privilege</primary>
16319    </indexterm>
16320    <indexterm>
16321     <primary>has_tablespace_privilege</primary>
16322    </indexterm>
16323    <indexterm>
16324     <primary>has_type_privilege</primary>
16325    </indexterm>
16326    <indexterm>
16327     <primary>pg_has_role</primary>
16328    </indexterm>
16329    <indexterm>
16330     <primary>row_security_active</primary>
16331    </indexterm>
16332
16333    <para>
16334     <function>has_table_privilege</function> checks whether a user
16335     can access a table in a particular way.  The user can be
16336     specified by name, by OID (<literal>pg_authid.oid</literal>),
16337     <literal>public</> to indicate the PUBLIC pseudo-role, or if the argument is
16338     omitted
16339     <function>current_user</function> is assumed.  The table can be specified
16340     by name or by OID.  (Thus, there are actually six variants of
16341     <function>has_table_privilege</function>, which can be distinguished by
16342     the number and types of their arguments.)  When specifying by name,
16343     the name can be schema-qualified if necessary.
16344     The desired access privilege type
16345     is specified by a text string, which must evaluate to one of the
16346     values <literal>SELECT</literal>, <literal>INSERT</literal>,
16347     <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
16348     <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.  Optionally,
16349     <literal>WITH GRANT OPTION</> can be added to a privilege type to test
16350     whether the privilege is held with grant option.  Also, multiple privilege
16351     types can be listed separated by commas, in which case the result will
16352     be <literal>true</> if any of the listed privileges is held.
16353     (Case of the privilege string is not significant, and extra whitespace
16354     is allowed between but not within privilege names.)
16355     Some examples:
16356 <programlisting>
16357 SELECT has_table_privilege('myschema.mytable', 'select');
16358 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
16359 </programlisting>
16360    </para>
16361
16362    <para>
16363     <function>has_sequence_privilege</function> checks whether a user
16364     can access a sequence in a particular way.  The possibilities for its
16365     arguments are analogous to <function>has_table_privilege</function>.
16366     The desired access privilege type must evaluate to one of
16367     <literal>USAGE</literal>,
16368     <literal>SELECT</literal>, or
16369     <literal>UPDATE</literal>.
16370    </para>
16371
16372    <para>
16373     <function>has_any_column_privilege</function> checks whether a user can
16374     access any column of a table in a particular way.
16375     Its argument possibilities
16376     are analogous to <function>has_table_privilege</>,
16377     except that the desired access privilege type must evaluate to some
16378     combination of
16379     <literal>SELECT</literal>,
16380     <literal>INSERT</literal>,
16381     <literal>UPDATE</literal>, or
16382     <literal>REFERENCES</literal>.  Note that having any of these privileges
16383     at the table level implicitly grants it for each column of the table,
16384     so <function>has_any_column_privilege</function> will always return
16385     <literal>true</> if <function>has_table_privilege</> does for the same
16386     arguments.  But <function>has_any_column_privilege</> also succeeds if
16387     there is a column-level grant of the privilege for at least one column.
16388    </para>
16389
16390    <para>
16391     <function>has_column_privilege</function> checks whether a user
16392     can access a column in a particular way.
16393     Its argument possibilities
16394     are analogous to <function>has_table_privilege</function>,
16395     with the addition that the column can be specified either by name
16396     or attribute number.
16397     The desired access privilege type must evaluate to some combination of
16398     <literal>SELECT</literal>,
16399     <literal>INSERT</literal>,
16400     <literal>UPDATE</literal>, or
16401     <literal>REFERENCES</literal>.  Note that having any of these privileges
16402     at the table level implicitly grants it for each column of the table.
16403    </para>
16404
16405    <para>
16406     <function>has_database_privilege</function> checks whether a user
16407     can access a database in a particular way.
16408     Its argument possibilities
16409     are analogous to <function>has_table_privilege</function>.
16410     The desired access privilege type must evaluate to some combination of
16411     <literal>CREATE</literal>,
16412     <literal>CONNECT</literal>,
16413     <literal>TEMPORARY</literal>, or
16414     <literal>TEMP</literal> (which is equivalent to
16415     <literal>TEMPORARY</literal>).
16416    </para>
16417
16418    <para>
16419     <function>has_function_privilege</function> checks whether a user
16420     can access a function in a particular way.
16421     Its argument possibilities
16422     are analogous to <function>has_table_privilege</function>.
16423     When specifying a function by a text string rather than by OID,
16424     the allowed input is the same as for the <type>regprocedure</> data type
16425     (see <xref linkend="datatype-oid">).
16426     The desired access privilege type must evaluate to
16427     <literal>EXECUTE</literal>.
16428     An example is:
16429 <programlisting>
16430 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
16431 </programlisting>
16432    </para>
16433
16434    <para>
16435     <function>has_foreign_data_wrapper_privilege</function> checks whether a user
16436     can access a foreign-data wrapper in a particular way.
16437     Its argument possibilities
16438     are analogous to <function>has_table_privilege</function>.
16439     The desired access privilege type must evaluate to
16440     <literal>USAGE</literal>.
16441    </para>
16442
16443    <para>
16444     <function>has_language_privilege</function> checks whether a user
16445     can access a procedural language in a particular way.
16446     Its argument possibilities
16447     are analogous to <function>has_table_privilege</function>.
16448     The desired access privilege type must evaluate to
16449     <literal>USAGE</literal>.
16450    </para>
16451
16452    <para>
16453     <function>has_schema_privilege</function> checks whether a user
16454     can access a schema in a particular way.
16455     Its argument possibilities
16456     are analogous to <function>has_table_privilege</function>.
16457     The desired access privilege type must evaluate to some combination of
16458     <literal>CREATE</literal> or
16459     <literal>USAGE</literal>.
16460    </para>
16461
16462    <para>
16463     <function>has_server_privilege</function> checks whether a user
16464     can access a foreign server in a particular way.
16465     Its argument possibilities
16466     are analogous to <function>has_table_privilege</function>.
16467     The desired access privilege type must evaluate to
16468     <literal>USAGE</literal>.
16469    </para>
16470
16471    <para>
16472     <function>has_tablespace_privilege</function> checks whether a user
16473     can access a tablespace in a particular way.
16474     Its argument possibilities
16475     are analogous to <function>has_table_privilege</function>.
16476     The desired access privilege type must evaluate to
16477     <literal>CREATE</literal>.
16478    </para>
16479
16480    <para>
16481     <function>has_type_privilege</function> checks whether a user
16482     can access a type in a particular way.
16483     Its argument possibilities
16484     are analogous to <function>has_table_privilege</function>.
16485     When specifying a type by a text string rather than by OID,
16486     the allowed input is the same as for the <type>regtype</> data type
16487     (see <xref linkend="datatype-oid">).
16488     The desired access privilege type must evaluate to
16489     <literal>USAGE</literal>.
16490    </para>
16491
16492    <para>
16493     <function>pg_has_role</function> checks whether a user
16494     can access a role in a particular way.
16495     Its argument possibilities
16496     are analogous to <function>has_table_privilege</function>,
16497     except that <literal>public</> is not allowed as a user name.
16498     The desired access privilege type must evaluate to some combination of
16499     <literal>MEMBER</literal> or
16500     <literal>USAGE</literal>.
16501     <literal>MEMBER</literal> denotes direct or indirect membership in
16502     the role (that is, the right to do <command>SET ROLE</>), while
16503     <literal>USAGE</literal> denotes whether the privileges of the role
16504     are immediately available without doing <command>SET ROLE</>.
16505    </para>
16506
16507    <para>
16508     <function>row_security_active</function> checks whether row level
16509     security is active for the specified table in the context of the
16510     <function>current_user</function> and environment. The table can
16511     be specified by name or by OID.
16512    </para>
16513
16514   <para>
16515    <xref linkend="functions-info-schema-table"> shows functions that
16516    determine whether a certain object is <firstterm>visible</> in the
16517    current schema search path.
16518    For example, a table is said to be visible if its
16519    containing schema is in the search path and no table of the same
16520    name appears earlier in the search path.  This is equivalent to the
16521    statement that the table can be referenced by name without explicit
16522    schema qualification.  To list the names of all visible tables:
16523 <programlisting>
16524 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
16525 </programlisting>
16526   </para>
16527
16528    <indexterm>
16529     <primary>search path</primary>
16530     <secondary>object visibility</secondary>
16531    </indexterm>
16532
16533    <table id="functions-info-schema-table">
16534     <title>Schema Visibility Inquiry Functions</title>
16535     <tgroup cols="3">
16536      <thead>
16537       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
16538      </thead>
16539
16540      <tbody>
16541       <row>
16542        <entry><literal><function>pg_collation_is_visible(<parameter>collation_oid</parameter>)</function></literal>
16543        </entry>
16544        <entry><type>boolean</type></entry>
16545        <entry>is collation visible in search path</entry>
16546       </row>
16547       <row>
16548        <entry><literal><function>pg_conversion_is_visible(<parameter>conversion_oid</parameter>)</function></literal>
16549        </entry>
16550        <entry><type>boolean</type></entry>
16551        <entry>is conversion visible in search path</entry>
16552       </row>
16553       <row>
16554        <entry><literal><function>pg_function_is_visible(<parameter>function_oid</parameter>)</function></literal>
16555        </entry>
16556        <entry><type>boolean</type></entry>
16557        <entry>is function visible in search path</entry>
16558       </row>
16559       <row>
16560        <entry><literal><function>pg_opclass_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
16561        </entry>
16562        <entry><type>boolean</type></entry>
16563        <entry>is operator class visible in search path</entry>
16564       </row>
16565       <row>
16566        <entry><literal><function>pg_operator_is_visible(<parameter>operator_oid</parameter>)</function></literal>
16567        </entry>
16568        <entry><type>boolean</type></entry>
16569        <entry>is operator visible in search path</entry>
16570       </row>
16571       <row>
16572        <entry><literal><function>pg_opfamily_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
16573        </entry>
16574        <entry><type>boolean</type></entry>
16575        <entry>is operator family visible in search path</entry>
16576       </row>
16577       <row>
16578        <entry><literal><function>pg_table_is_visible(<parameter>table_oid</parameter>)</function></literal>
16579        </entry>
16580        <entry><type>boolean</type></entry>
16581        <entry>is table visible in search path</entry>
16582       </row>
16583       <row>
16584        <entry><literal><function>pg_ts_config_is_visible(<parameter>config_oid</parameter>)</function></literal>
16585        </entry>
16586        <entry><type>boolean</type></entry>
16587        <entry>is text search configuration visible in search path</entry>
16588       </row>
16589       <row>
16590        <entry><literal><function>pg_ts_dict_is_visible(<parameter>dict_oid</parameter>)</function></literal>
16591        </entry>
16592        <entry><type>boolean</type></entry>
16593        <entry>is text search dictionary visible in search path</entry>
16594       </row>
16595       <row>
16596        <entry><literal><function>pg_ts_parser_is_visible(<parameter>parser_oid</parameter>)</function></literal>
16597        </entry>
16598        <entry><type>boolean</type></entry>
16599        <entry>is text search parser visible in search path</entry>
16600       </row>
16601       <row>
16602        <entry><literal><function>pg_ts_template_is_visible(<parameter>template_oid</parameter>)</function></literal>
16603        </entry>
16604        <entry><type>boolean</type></entry>
16605        <entry>is text search template visible in search path</entry>
16606       </row>
16607       <row>
16608        <entry><literal><function>pg_type_is_visible(<parameter>type_oid</parameter>)</function></literal>
16609        </entry>
16610        <entry><type>boolean</type></entry>
16611        <entry>is type (or domain) visible in search path</entry>
16612       </row>
16613      </tbody>
16614     </tgroup>
16615    </table>
16616
16617    <indexterm>
16618     <primary>pg_collation_is_visible</primary>
16619    </indexterm>
16620    <indexterm>
16621     <primary>pg_conversion_is_visible</primary>
16622    </indexterm>
16623    <indexterm>
16624     <primary>pg_function_is_visible</primary>
16625    </indexterm>
16626    <indexterm>
16627     <primary>pg_opclass_is_visible</primary>
16628    </indexterm>
16629    <indexterm>
16630     <primary>pg_operator_is_visible</primary>
16631    </indexterm>
16632    <indexterm>
16633     <primary>pg_opfamily_is_visible</primary>
16634    </indexterm>
16635    <indexterm>
16636     <primary>pg_table_is_visible</primary>
16637    </indexterm>
16638    <indexterm>
16639     <primary>pg_ts_config_is_visible</primary>
16640    </indexterm>
16641    <indexterm>
16642     <primary>pg_ts_dict_is_visible</primary>
16643    </indexterm>
16644    <indexterm>
16645     <primary>pg_ts_parser_is_visible</primary>
16646    </indexterm>
16647    <indexterm>
16648     <primary>pg_ts_template_is_visible</primary>
16649    </indexterm>
16650    <indexterm>
16651     <primary>pg_type_is_visible</primary>
16652    </indexterm>
16653
16654    <para>
16655     Each function performs the visibility check for one type of database
16656     object.  Note that <function>pg_table_is_visible</function> can also be used
16657     with views, materialized views, indexes, sequences and foreign tables;
16658     <function>pg_type_is_visible</function> can also be used with domains.
16659     For functions and operators, an object in
16660     the search path is visible if there is no object of the same name
16661     <emphasis>and argument data type(s)</> earlier in the path.  For operator
16662     classes, both name and associated index access method are considered.
16663    </para>
16664
16665    <para>
16666     All these functions require object OIDs to identify the object to be
16667     checked.  If you want to test an object by name, it is convenient to use
16668     the OID alias types (<type>regclass</>, <type>regtype</>,
16669     <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
16670     or <type>regdictionary</>),
16671     for example:
16672 <programlisting>
16673 SELECT pg_type_is_visible('myschema.widget'::regtype);
16674 </programlisting>
16675     Note that it would not make much sense to test a non-schema-qualified
16676     type name in this way &mdash; if the name can be recognized at all, it must be visible.
16677    </para>
16678
16679    <indexterm>
16680     <primary>format_type</primary>
16681    </indexterm>
16682
16683    <indexterm>
16684     <primary>pg_get_constraintdef</primary>
16685    </indexterm>
16686
16687    <indexterm>
16688     <primary>pg_get_expr</primary>
16689    </indexterm>
16690
16691    <indexterm>
16692     <primary>pg_get_functiondef</primary>
16693    </indexterm>
16694
16695    <indexterm>
16696     <primary>pg_get_function_arguments</primary>
16697    </indexterm>
16698
16699    <indexterm>
16700     <primary>pg_get_function_identity_arguments</primary>
16701    </indexterm>
16702
16703    <indexterm>
16704     <primary>pg_get_function_result</primary>
16705    </indexterm>
16706
16707    <indexterm>
16708     <primary>pg_get_indexdef</primary>
16709    </indexterm>
16710
16711    <indexterm>
16712     <primary>pg_get_keywords</primary>
16713    </indexterm>
16714
16715    <indexterm>
16716     <primary>pg_get_ruledef</primary>
16717    </indexterm>
16718
16719    <indexterm>
16720     <primary>pg_get_serial_sequence</primary>
16721    </indexterm>
16722
16723    <indexterm>
16724     <primary>pg_get_triggerdef</primary>
16725    </indexterm>
16726
16727    <indexterm>
16728     <primary>pg_get_userbyid</primary>
16729    </indexterm>
16730
16731    <indexterm>
16732     <primary>pg_get_viewdef</primary>
16733    </indexterm>
16734
16735    <indexterm>
16736     <primary>pg_index_column_has_property</primary>
16737    </indexterm>
16738
16739    <indexterm>
16740     <primary>pg_index_has_property</primary>
16741    </indexterm>
16742
16743    <indexterm>
16744     <primary>pg_indexam_has_property</primary>
16745    </indexterm>
16746
16747    <indexterm>
16748     <primary>pg_options_to_table</primary>
16749    </indexterm>
16750
16751    <indexterm>
16752     <primary>pg_tablespace_databases</primary>
16753    </indexterm>
16754
16755    <indexterm>
16756     <primary>pg_tablespace_location</primary>
16757    </indexterm>
16758
16759    <indexterm>
16760     <primary>pg_typeof</primary>
16761    </indexterm>
16762
16763    <indexterm>
16764     <primary>collation for</primary>
16765    </indexterm>
16766
16767    <indexterm>
16768     <primary>to_regclass</primary>
16769    </indexterm>
16770
16771    <indexterm>
16772     <primary>to_regproc</primary>
16773    </indexterm>
16774
16775    <indexterm>
16776     <primary>to_regprocedure</primary>
16777    </indexterm>
16778
16779    <indexterm>
16780     <primary>to_regoper</primary>
16781    </indexterm>
16782
16783    <indexterm>
16784     <primary>to_regoperator</primary>
16785    </indexterm>
16786
16787    <indexterm>
16788     <primary>to_regtype</primary>
16789    </indexterm>
16790
16791    <indexterm>
16792     <primary>to_regnamespace</primary>
16793    </indexterm>
16794
16795    <indexterm>
16796     <primary>to_regrole</primary>
16797    </indexterm>
16798
16799   <para>
16800    <xref linkend="functions-info-catalog-table"> lists functions that
16801    extract information from the system catalogs.
16802   </para>
16803
16804    <table id="functions-info-catalog-table">
16805     <title>System Catalog Information Functions</title>
16806     <tgroup cols="3">
16807      <thead>
16808       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
16809      </thead>
16810
16811      <tbody>
16812       <row>
16813        <entry><literal><function>format_type(<parameter>type_oid</parameter>, <parameter>typemod</>)</function></literal></entry>
16814        <entry><type>text</type></entry>
16815        <entry>get SQL name of a data type</entry>
16816       </row>
16817       <row>
16818        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>)</function></literal></entry>
16819        <entry><type>text</type></entry>
16820        <entry>get definition of a constraint</entry>
16821       </row>
16822       <row>
16823        <entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
16824        <entry><type>text</type></entry>
16825        <entry>get definition of a constraint</entry>
16826       </row>
16827       <row>
16828        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>)</function></literal></entry>
16829        <entry><type>text</type></entry>
16830        <entry>decompile internal form of an expression, assuming that any Vars
16831        in it refer to the relation indicated by the second parameter</entry>
16832       </row>
16833       <row>
16834        <entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</function></literal></entry>
16835        <entry><type>text</type></entry>
16836        <entry>decompile internal form of an expression, assuming that any Vars
16837        in it refer to the relation indicated by the second parameter</entry>
16838       </row>
16839       <row>
16840        <entry><literal><function>pg_get_functiondef(<parameter>func_oid</parameter>)</function></literal></entry>
16841        <entry><type>text</type></entry>
16842        <entry>get definition of a function</entry>
16843       </row>
16844       <row>
16845        <entry><literal><function>pg_get_function_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
16846        <entry><type>text</type></entry>
16847        <entry>get argument list of function's definition (with default values)</entry>
16848       </row>
16849       <row>
16850        <entry><literal><function>pg_get_function_identity_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
16851        <entry><type>text</type></entry>
16852        <entry>get argument list to identify a function (without default values)</entry>
16853       </row>
16854       <row>
16855        <entry><literal><function>pg_get_function_result(<parameter>func_oid</parameter>)</function></literal></entry>
16856        <entry><type>text</type></entry>
16857        <entry>get <literal>RETURNS</> clause for function</entry>
16858       </row>
16859       <row>
16860        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>)</function></literal></entry>
16861        <entry><type>text</type></entry>
16862        <entry>get <command>CREATE INDEX</> command for index</entry>
16863       </row>
16864       <row>
16865        <entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</function></literal></entry>
16866        <entry><type>text</type></entry>
16867        <entry>get <command>CREATE INDEX</> command for index,
16868        or definition of just one index column when
16869        <parameter>column_no</> is not zero</entry>
16870       </row>
16871       <row>
16872        <entry><literal><function>pg_get_keywords()</function></literal></entry>
16873        <entry><type>setof record</type></entry>
16874        <entry>get list of SQL keywords and their categories</entry>
16875       </row>
16876       <row>
16877        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>)</function></literal></entry>
16878        <entry><type>text</type></entry>
16879        <entry>get <command>CREATE RULE</> command for rule</entry>
16880       </row>
16881       <row>
16882        <entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
16883        <entry><type>text</type></entry>
16884        <entry>get <command>CREATE RULE</> command for rule</entry>
16885       </row>
16886       <row>
16887        <entry><literal><function>pg_get_serial_sequence(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</function></literal></entry>
16888        <entry><type>text</type></entry>
16889        <entry>get name of the sequence that a <type>serial</type>, <type>smallserial</type> or <type>bigserial</type> column
16890        uses</entry>
16891       </row>
16892       <row>
16893        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
16894        <entry><type>text</type></entry>
16895        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
16896       </row>
16897       <row>
16898        <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>, <parameter>pretty_bool</>)</entry>
16899        <entry><type>text</type></entry>
16900        <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
16901       </row>
16902       <row>
16903        <entry><literal><function>pg_get_userbyid(<parameter>role_oid</parameter>)</function></literal></entry>
16904        <entry><type>name</type></entry>
16905        <entry>get role name with given OID</entry>
16906       </row>
16907       <row>
16908        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>)</function></literal></entry>
16909        <entry><type>text</type></entry>
16910        <entry>get underlying <command>SELECT</command> command for view or materialized view (<emphasis>deprecated</emphasis>)</entry>
16911       </row>
16912       <row>
16913        <entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
16914        <entry><type>text</type></entry>
16915        <entry>get underlying <command>SELECT</command> command for view or materialized view (<emphasis>deprecated</emphasis>)</entry>
16916       </row>
16917       <row>
16918        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>)</function></literal></entry>
16919        <entry><type>text</type></entry>
16920        <entry>get underlying <command>SELECT</command> command for view or materialized view</entry>
16921       </row>
16922       <row>
16923        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
16924        <entry><type>text</type></entry>
16925        <entry>get underlying <command>SELECT</command> command for view or materialized view</entry>
16926       </row>
16927       <row>
16928        <entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>wrap_column_int</>)</function></literal></entry>
16929        <entry><type>text</type></entry>
16930        <entry>get underlying <command>SELECT</command> command for view or
16931               materialized view; lines with fields are wrapped to specified
16932               number of columns, pretty-printing is implied</entry>
16933       </row>
16934       <row>
16935        <entry><literal><function>pg_index_column_has_property(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>prop_name</>)</function></literal></entry>
16936        <entry><type>boolean</type></entry>
16937        <entry>test whether an index column has a specified property</entry>
16938       </row>
16939       <row>
16940        <entry><literal><function>pg_index_has_property(<parameter>index_oid</parameter>, <parameter>prop_name</>)</function></literal></entry>
16941        <entry><type>boolean</type></entry>
16942        <entry>test whether an index has a specified property</entry>
16943       </row>
16944       <row>
16945        <entry><literal><function>pg_indexam_has_property(<parameter>am_oid</parameter>, <parameter>prop_name</>)</function></literal></entry>
16946        <entry><type>boolean</type></entry>
16947        <entry>test whether an index access method has a specified property</entry>
16948       </row>
16949       <row>
16950        <entry><literal><function>pg_options_to_table(<parameter>reloptions</parameter>)</function></literal></entry>
16951        <entry><type>setof record</type></entry>
16952        <entry>get the set of storage option name/value pairs</entry>
16953       </row>
16954       <row>
16955        <entry><literal><function>pg_tablespace_databases(<parameter>tablespace_oid</parameter>)</function></literal></entry>
16956        <entry><type>setof oid</type></entry>
16957        <entry>get the set of database OIDs that have objects in the tablespace</entry>
16958       </row>
16959       <row>
16960        <entry><literal><function>pg_tablespace_location(<parameter>tablespace_oid</parameter>)</function></literal></entry>
16961        <entry><type>text</type></entry>
16962        <entry>get the path in the file system that this tablespace is located in</entry>
16963       </row>
16964       <row>
16965        <entry><literal><function>pg_typeof(<parameter>any</parameter>)</function></literal></entry>
16966        <entry><type>regtype</type></entry>
16967        <entry>get the data type of any value</entry>
16968       </row>
16969       <row>
16970        <entry><literal><function>collation for (<parameter>any</parameter>)</function></literal></entry>
16971        <entry><type>text</type></entry>
16972        <entry>get the collation of the argument</entry>
16973       </row>
16974       <row>
16975        <entry><literal><function>to_regclass(<parameter>rel_name</parameter>)</function></literal></entry>
16976        <entry><type>regclass</type></entry>
16977        <entry>get the OID of the named relation</entry>
16978       </row>
16979       <row>
16980        <entry><literal><function>to_regproc(<parameter>func_name</parameter>)</function></literal></entry>
16981        <entry><type>regproc</type></entry>
16982        <entry>get the OID of the named function</entry>
16983       </row>
16984       <row>
16985        <entry><literal><function>to_regprocedure(<parameter>func_name</parameter>)</function></literal></entry>
16986        <entry><type>regprocedure</type></entry>
16987        <entry>get the OID of the named function</entry>
16988       </row>
16989       <row>
16990        <entry><literal><function>to_regoper(<parameter>operator_name</parameter>)</function></literal></entry>
16991        <entry><type>regoper</type></entry>
16992        <entry>get the OID of the named operator</entry>
16993       </row>
16994       <row>
16995        <entry><literal><function>to_regoperator(<parameter>operator_name</parameter>)</function></literal></entry>
16996        <entry><type>regoperator</type></entry>
16997        <entry>get the OID of the named operator</entry>
16998       </row>
16999       <row>
17000        <entry><literal><function>to_regtype(<parameter>type_name</parameter>)</function></literal></entry>
17001        <entry><type>regtype</type></entry>
17002        <entry>get the OID of the named type</entry>
17003       </row>
17004       <row>
17005        <entry><literal><function>to_regnamespace(<parameter>schema_name</parameter>)</function></literal></entry>
17006        <entry><type>regnamespace</type></entry>
17007        <entry>get the OID of the named schema</entry>
17008       </row>
17009       <row>
17010        <entry><literal><function>to_regrole(<parameter>role_name</parameter>)</function></literal></entry>
17011        <entry><type>regrole</type></entry>
17012        <entry>get the OID of the named role</entry>
17013       </row>
17014      </tbody>
17015     </tgroup>
17016    </table>
17017
17018   <para>
17019    <function>format_type</function> returns the SQL name of a data type that
17020    is identified by its type OID and possibly a type modifier.  Pass NULL
17021    for the type modifier if no specific modifier is known.
17022   </para>
17023
17024   <para>
17025    <function>pg_get_keywords</function> returns a set of records describing
17026    the SQL keywords recognized by the server. The <structfield>word</> column
17027    contains the keyword.  The <structfield>catcode</> column contains a
17028    category code: <literal>U</> for unreserved, <literal>C</> for column name,
17029    <literal>T</> for type or function name, or <literal>R</> for reserved.
17030    The <structfield>catdesc</> column contains a possibly-localized string
17031    describing the category.
17032   </para>
17033
17034   <para>
17035    <function>pg_get_constraintdef</function>,
17036    <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
17037    and <function>pg_get_triggerdef</function>, respectively reconstruct the
17038    creating command for a constraint, index, rule, or trigger. (Note that this
17039    is a decompiled reconstruction, not the original text of the command.)
17040    <function>pg_get_expr</function> decompiles the internal form of an
17041    individual expression, such as the default value for a column.  It can be
17042    useful when examining the contents of system catalogs.  If the expression
17043    might contain Vars, specify the OID of the relation they refer to as the
17044    second parameter; if no Vars are expected, zero is sufficient.
17045    <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
17046    query that defines a view. Most of these functions come in two variants,
17047    one of which can optionally <quote>pretty-print</> the result.  The
17048    pretty-printed format is more readable, but the default format is more
17049    likely to be interpreted the same way by future versions of
17050    <productname>PostgreSQL</>; avoid using pretty-printed output for dump
17051    purposes.  Passing <literal>false</> for the pretty-print parameter yields
17052    the same result as the variant that does not have the parameter at all.
17053   </para>
17054
17055   <para>
17056    <function>pg_get_functiondef</> returns a complete
17057    <command>CREATE OR REPLACE FUNCTION</> statement for a function.
17058    <function>pg_get_function_arguments</function> returns the argument list
17059    of a function, in the form it would need to appear in within
17060    <command>CREATE FUNCTION</>.
17061    <function>pg_get_function_result</function> similarly returns the
17062    appropriate <literal>RETURNS</> clause for the function.
17063    <function>pg_get_function_identity_arguments</function> returns the
17064    argument list necessary to identify a function, in the form it
17065    would need to appear in within <command>ALTER FUNCTION</>, for
17066    instance.  This form omits default values.
17067   </para>
17068
17069   <para>
17070    <function>pg_get_serial_sequence</function> returns the name of the
17071    sequence associated with a column, or NULL if no sequence is associated
17072    with the column.  The first input parameter is a table name with
17073    optional schema, and the second parameter is a column name.  Because
17074    the first parameter is potentially a schema and table, it is not treated
17075    as a double-quoted identifier, meaning it is lower cased by default,
17076    while the second parameter, being just a column name, is treated as
17077    double-quoted and has its case preserved.  The function returns a value
17078    suitably formatted for passing to sequence functions (see <xref
17079    linkend="functions-sequence">).  This association can be modified or
17080    removed with <command>ALTER SEQUENCE OWNED BY</>.  (The function
17081    probably should have been called
17082    <function>pg_get_owned_sequence</function>; its current name reflects the fact
17083    that it's typically used with <type>serial</> or <type>bigserial</>
17084    columns.)
17085   </para>
17086
17087   <para>
17088    <function>pg_get_userbyid</function> extracts a role's name given
17089    its OID.
17090   </para>
17091
17092   <para>
17093    <function>pg_index_column_has_property</function>,
17094    <function>pg_index_has_property</function>, and
17095    <function>pg_indexam_has_property</function> return whether the
17096    specified index column, index, or index access method possesses the named
17097    property. <literal>NULL</literal> is returned if the property name is not
17098    known or does not apply to the particular object, or if the OID or column
17099    number does not identify a valid object.  Refer to
17100    <xref linkend="functions-info-index-column-props"> for column properties,
17101    <xref linkend="functions-info-index-props"> for index properties, and
17102    <xref linkend="functions-info-indexam-props"> for access method properties.
17103    (Note that extension access methods can define additional property names
17104    for their indexes.)
17105   </para>
17106
17107   <table id="functions-info-index-column-props">
17108    <title>Index Column Properties</title>
17109    <tgroup cols="2">
17110     <thead>
17111      <row><entry>Name</entry><entry>Description</entry></row>
17112     </thead>
17113     <tbody>
17114      <row>
17115       <entry><literal>asc</literal></entry>
17116       <entry>Does the column sort in ascending order on a forward scan?
17117       </entry>
17118      </row>
17119      <row>
17120       <entry><literal>desc</literal></entry>
17121       <entry>Does the column sort in descending order on a forward scan?
17122       </entry>
17123      </row>
17124      <row>
17125       <entry><literal>nulls_first</literal></entry>
17126       <entry>Does the column sort with nulls first on a forward scan?
17127       </entry>
17128      </row>
17129      <row>
17130       <entry><literal>nulls_last</literal></entry>
17131       <entry>Does the column sort with nulls last on a forward scan?
17132       </entry>
17133      </row>
17134      <row>
17135       <entry><literal>orderable</literal></entry>
17136       <entry>Does the column possess any defined sort ordering?
17137       </entry>
17138      </row>
17139      <row>
17140       <entry><literal>distance_orderable</literal></entry>
17141       <entry>Can the column be scanned in order by a <quote>distance</>
17142       operator, for example <literal>ORDER BY col &lt;-&gt; constant</> ?
17143       </entry>
17144      </row>
17145      <row>
17146       <entry><literal>returnable</literal></entry>
17147       <entry>Can the column value be returned by an index-only scan?
17148       </entry>
17149      </row>
17150      <row>
17151       <entry><literal>search_array</literal></entry>
17152       <entry>Does the column natively support <literal>col = ANY(array)</>
17153       searches?
17154       </entry>
17155      </row>
17156      <row>
17157       <entry><literal>search_nulls</literal></entry>
17158       <entry>Does the column support <literal>IS NULL</> and
17159       <literal>IS NOT NULL</> searches?
17160       </entry>
17161      </row>
17162     </tbody>
17163    </tgroup>
17164   </table>
17165
17166   <table id="functions-info-index-props">
17167    <title>Index Properties</title>
17168    <tgroup cols="2">
17169     <thead>
17170      <row><entry>Name</entry><entry>Description</entry></row>
17171     </thead>
17172     <tbody>
17173      <row>
17174       <entry><literal>clusterable</literal></entry>
17175       <entry>Can the index be used in a <literal>CLUSTER</> command?
17176       </entry>
17177      </row>
17178      <row>
17179       <entry><literal>index_scan</literal></entry>
17180       <entry>Does the index support plain (non-bitmap) scans?
17181       </entry>
17182      </row>
17183      <row>
17184       <entry><literal>bitmap_scan</literal></entry>
17185       <entry>Does the index support bitmap scans?
17186       </entry>
17187      </row>
17188      <row>
17189       <entry><literal>backward_scan</literal></entry>
17190       <entry>Can the index be scanned backwards?
17191       </entry>
17192      </row>
17193     </tbody>
17194    </tgroup>
17195   </table>
17196
17197   <table id="functions-info-indexam-props">
17198    <title>Index Access Method Properties</title>
17199    <tgroup cols="2">
17200     <thead>
17201      <row><entry>Name</entry><entry>Description</entry></row>
17202     </thead>
17203     <tbody>
17204      <row>
17205       <entry><literal>can_order</literal></entry>
17206       <entry>Does the access method support <literal>ASC</>,
17207       <literal>DESC</> and related keywords in
17208       <literal>CREATE INDEX</>?
17209       </entry>
17210      </row>
17211      <row>
17212       <entry><literal>can_unique</literal></entry>
17213       <entry>Does the access method support unique indexes?
17214       </entry>
17215      </row>
17216      <row>
17217       <entry><literal>can_multi_col</literal></entry>
17218       <entry>Does the access method support indexes with multiple columns?
17219       </entry>
17220      </row>
17221      <row>
17222       <entry><literal>can_exclude</literal></entry>
17223       <entry>Does the access method support exclusion constraints?
17224       </entry>
17225      </row>
17226     </tbody>
17227    </tgroup>
17228   </table>
17229
17230   <para>
17231    <function>pg_options_to_table</function> returns the set of storage
17232    option name/value pairs
17233    (<replaceable>option_name</>/<replaceable>option_value</>) when passed
17234    <structname>pg_class</>.<structfield>reloptions</> or
17235    <structname>pg_attribute</>.<structfield>attoptions</>.
17236   </para>
17237
17238   <para>
17239    <function>pg_tablespace_databases</function> allows a tablespace to be
17240    examined. It returns the set of OIDs of databases that have objects stored
17241    in the tablespace. If this function returns any rows, the tablespace is not
17242    empty and cannot be dropped. To display the specific objects populating the
17243    tablespace, you will need to connect to the databases identified by
17244    <function>pg_tablespace_databases</function> and query their
17245    <structname>pg_class</> catalogs.
17246   </para>
17247
17248   <para>
17249    <function>pg_typeof</function> returns the OID of the data type of the
17250    value that is passed to it.  This can be helpful for troubleshooting or
17251    dynamically constructing SQL queries.  The function is declared as
17252    returning <type>regtype</>, which is an OID alias type (see
17253    <xref linkend="datatype-oid">); this means that it is the same as an
17254    OID for comparison purposes but displays as a type name.  For example:
17255 <programlisting>
17256 SELECT pg_typeof(33);
17257
17258  pg_typeof 
17259 -----------
17260  integer
17261 (1 row)
17262
17263 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
17264  typlen 
17265 --------
17266       4
17267 (1 row)
17268 </programlisting>
17269   </para>
17270
17271   <para>
17272    The expression <literal>collation for</literal> returns the collation of the
17273    value that is passed to it.  Example:
17274 <programlisting>
17275 SELECT collation for (description) FROM pg_description LIMIT 1;
17276  pg_collation_for 
17277 ------------------
17278  "default"
17279 (1 row)
17280
17281 SELECT collation for ('foo' COLLATE "de_DE");
17282  pg_collation_for 
17283 ------------------
17284  "de_DE"
17285 (1 row)
17286 </programlisting>
17287   The value might be quoted and schema-qualified.  If no collation is derived
17288   for the argument expression, then a null value is returned.  If the argument
17289   is not of a collatable data type, then an error is raised.
17290   </para>
17291
17292   <para>
17293    The <function>to_regclass</function>, <function>to_regproc</function>,
17294    <function>to_regprocedure</function>, <function>to_regoper</function>,
17295    <function>to_regoperator</function>, <function>to_regtype</function>,
17296    <function>to_regnamespace</function>, and <function>to_regrole</function>
17297    functions translate relation, function, operator, type, schema, and role
17298    names (given as <type>text</>) to objects of
17299    type <type>regclass</>, <type>regproc</>, <type>regprocedure</type>,
17300    <type>regoper</>, <type>regoperator</type>, <type>regtype</>,
17301    <type>regnamespace</>, and <type>regrole</>
17302    respectively.  These functions differ from a cast from
17303    text in that they don't accept a numeric OID, and that they return null
17304    rather than throwing an error if the name is not found (or, for
17305    <function>to_regproc</function> and <function>to_regoper</function>, if
17306    the given name matches multiple objects).
17307   </para>
17308
17309    <indexterm>
17310     <primary>pg_describe_object</primary>
17311    </indexterm>
17312
17313    <indexterm>
17314     <primary>pg_identify_object</primary>
17315    </indexterm>
17316
17317    <indexterm>
17318     <primary>pg_identify_object_as_address</primary>
17319    </indexterm>
17320
17321    <indexterm>
17322     <primary>pg_get_object_address</primary>
17323    </indexterm>
17324
17325   <para>
17326    <xref linkend="functions-info-object-table"> lists functions related to
17327    database object identification and addressing.
17328   </para>
17329
17330    <table id="functions-info-object-table">
17331     <title>Object Information and Addressing Functions</title>
17332     <tgroup cols="3">
17333      <thead>
17334       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
17335      </thead>
17336
17337      <tbody>
17338       <row>
17339        <entry><literal><function>pg_describe_object(<parameter>catalog_id</parameter>, <parameter>object_id</parameter>, <parameter>object_sub_id</parameter>)</function></literal></entry>
17340        <entry><type>text</type></entry>
17341        <entry>get description of a database object</entry>
17342       </row>
17343       <row>
17344        <entry><literal><function>pg_identify_object(<parameter>catalog_id</parameter> <type>oid</>, <parameter>object_id</parameter> <type>oid</>, <parameter>object_sub_id</parameter> <type>integer</>)</function></literal></entry>
17345        <entry><parameter>type</> <type>text</>, <parameter>schema</> <type>text</>, <parameter>name</> <type>text</>, <parameter>identity</> <type>text</></entry>
17346        <entry>get identity of a database object</entry>
17347       </row>
17348       <row>
17349        <entry><literal><function>pg_identify_object_as_address(<parameter>catalog_id</parameter> <type>oid</>, <parameter>object_id</parameter> <type>oid</>, <parameter>object_sub_id</parameter> <type>integer</>)</function></literal></entry>
17350        <entry><parameter>type</> <type>text</>, <parameter>name</> <type>text[]</>, <parameter>args</> <type>text[]</></entry>
17351        <entry>get external representation of a database object's address</entry>
17352       </row>
17353       <row>
17354        <entry><literal><function>pg_get_object_address(<parameter>type</parameter> <type>text</>, <parameter>name</parameter> <type>text[]</>, <parameter>args</parameter> <type>text[]</>)</function></literal></entry>
17355        <entry><parameter>catalog_id</> <type>oid</>, <parameter>object_id</> <type>oid</>, <parameter>object_sub_id</> <type>int32</></entry>
17356        <entry>get address of a database object, from its external representation</entry>
17357       </row>
17358      </tbody>
17359     </tgroup>
17360    </table>
17361
17362   <para>
17363    <function>pg_describe_object</function> returns a textual description of a database
17364    object specified by catalog OID, object OID and a (possibly zero) sub-object ID.
17365    This description is intended to be human-readable, and might be translated,
17366    depending on server configuration.
17367    This is useful to determine the identity of an object as stored in the
17368    <structname>pg_depend</structname> catalog.
17369   </para>
17370
17371   <para>
17372    <function>pg_identify_object</function> returns a row containing enough information
17373    to uniquely identify the database object specified by catalog OID, object OID and a
17374    (possibly zero) sub-object ID.  This information is intended to be machine-readable,
17375    and is never translated.
17376    <parameter>type</> identifies the type of database object;
17377    <parameter>schema</> is the schema name that the object belongs in, or
17378    <literal>NULL</> for object types that do not belong to schemas;
17379    <parameter>name</> is the name of the object, quoted if necessary, only
17380    present if it can be used (alongside schema name, if pertinent) as a unique
17381    identifier of the object, otherwise <literal>NULL</>;
17382    <parameter>identity</> is the complete object identity, with the precise format
17383    depending on object type, and each part within the format being
17384    schema-qualified and quoted as necessary.
17385   </para>
17386
17387   <para>
17388    <function>pg_identify_object_as_address</function> returns a row containing
17389    enough information to uniquely identify the database object specified by
17390    catalog OID, object OID and a (possibly zero) sub-object ID.  The returned
17391    information is independent of the current server, that is, it could be used
17392    to identify an identically named object in another server.
17393    <parameter>type</> identifies the type of database object;
17394    <parameter>name</> and <parameter>args</> are text arrays that together
17395    form a reference to the object.  These three columns can be passed to
17396    <function>pg_get_object_address</> to obtain the internal address
17397    of the object.
17398    This function is the inverse of <function>pg_get_object_address</function>.
17399   </para>
17400
17401   <para>
17402    <function>pg_get_object_address</function> returns a row containing enough
17403    information to uniquely identify the database object specified by its
17404    type and object name and argument arrays.  The returned values are the
17405    ones that would be used in system catalogs such as <structname>pg_depend</>
17406    and can be passed to other system functions such as
17407    <function>pg_identify_object</> or <function>pg_describe_object</>.
17408    <parameter>catalog_id</> is the OID of the system catalog containing the
17409    object;
17410    <parameter>object_id</> is the OID of the object itself, and
17411    <parameter>object_sub_id</> is the object sub-ID, or zero if none.
17412    This function is the inverse of <function>pg_identify_object_as_address</function>.
17413   </para>
17414
17415    <indexterm>
17416     <primary>col_description</primary>
17417    </indexterm>
17418
17419    <indexterm>
17420     <primary>obj_description</primary>
17421    </indexterm>
17422
17423    <indexterm>
17424     <primary>shobj_description</primary>
17425    </indexterm>
17426
17427    <indexterm>
17428     <primary>comment</primary>
17429     <secondary sortas="database objects">about database objects</secondary>
17430    </indexterm>
17431
17432    <para>
17433     The functions shown in <xref linkend="functions-info-comment-table">
17434     extract comments previously stored with the <xref linkend="sql-comment">
17435     command.  A null value is returned if no
17436     comment could be found for the specified parameters.
17437    </para>
17438
17439    <table id="functions-info-comment-table">
17440     <title>Comment Information Functions</title>
17441     <tgroup cols="3">
17442      <thead>
17443       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
17444      </thead>
17445
17446      <tbody>
17447       <row>
17448        <entry><literal><function>col_description(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</function></literal></entry>
17449        <entry><type>text</type></entry>
17450        <entry>get comment for a table column</entry>
17451       </row>
17452       <row>
17453        <entry><literal><function>obj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
17454        <entry><type>text</type></entry>
17455        <entry>get comment for a database object</entry>
17456       </row>
17457       <row>
17458        <entry><literal><function>obj_description(<parameter>object_oid</parameter>)</function></literal></entry>
17459        <entry><type>text</type></entry>
17460        <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
17461       </row>
17462       <row>
17463        <entry><literal><function>shobj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
17464        <entry><type>text</type></entry>
17465        <entry>get comment for a shared database object</entry>
17466       </row>
17467      </tbody>
17468     </tgroup>
17469    </table>
17470
17471    <para>
17472     <function>col_description</function> returns the comment for a table
17473     column, which is specified by the OID of its table and its column number.
17474     (<function>obj_description</function> cannot be used for table columns
17475     since columns do not have OIDs of their own.)
17476    </para>
17477
17478    <para>
17479     The two-parameter form of <function>obj_description</function> returns the
17480     comment for a database object specified by its OID and the name of the
17481     containing system catalog.  For example,
17482     <literal>obj_description(123456,'pg_class')</literal>
17483     would retrieve the comment for the table with OID 123456.
17484     The one-parameter form of <function>obj_description</function> requires only
17485     the object OID.  It is deprecated since there is no guarantee that
17486     OIDs are unique across different system catalogs; therefore, the wrong
17487     comment might be returned.
17488    </para>
17489
17490    <para>
17491     <function>shobj_description</function> is used just like
17492     <function>obj_description</function> except it is used for retrieving
17493     comments on shared objects.  Some system catalogs are global to all
17494     databases within each cluster, and the descriptions for objects in them
17495     are stored globally as well.
17496    </para>
17497
17498    <indexterm>
17499     <primary>txid_current</primary>
17500    </indexterm>
17501
17502    <indexterm>
17503     <primary>txid_current_if_assigned</primary>
17504    </indexterm>
17505
17506    <indexterm>
17507     <primary>txid_current_snapshot</primary>
17508    </indexterm>
17509
17510    <indexterm>
17511     <primary>txid_snapshot_xip</primary>
17512    </indexterm>
17513
17514    <indexterm>
17515     <primary>txid_snapshot_xmax</primary>
17516    </indexterm>
17517
17518    <indexterm>
17519     <primary>txid_snapshot_xmin</primary>
17520    </indexterm>
17521
17522    <indexterm>
17523     <primary>txid_visible_in_snapshot</primary>
17524    </indexterm>
17525
17526    <para>
17527     The functions shown in <xref linkend="functions-txid-snapshot">
17528     provide server transaction information in an exportable form.  The main
17529     use of these functions is to determine which transactions were committed
17530     between two snapshots.
17531    </para>
17532
17533    <table id="functions-txid-snapshot">
17534     <title>Transaction IDs and Snapshots</title>
17535     <tgroup cols="3">
17536      <thead>
17537       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
17538      </thead>
17539
17540      <tbody>
17541       <row>
17542        <entry><literal><function>txid_current()</function></literal></entry>
17543        <entry><type>bigint</type></entry>
17544        <entry>get current transaction ID, assigning a new one if the current transaction does not have one</entry>
17545       </row>
17546       <row>
17547        <entry><literal><function>txid_current_if_assigned()</function></literal></entry>
17548        <entry><type>bigint</type></entry>
17549        <entry>same as <function>txid_current()</function> but returns null instead of assigning an xid if none is already assigned</entry>
17550       </row>
17551       <row>
17552        <entry><literal><function>txid_current_snapshot()</function></literal></entry>
17553        <entry><type>txid_snapshot</type></entry>
17554        <entry>get current snapshot</entry>
17555       </row>
17556       <row>
17557        <entry><literal><function>txid_snapshot_xip(<parameter>txid_snapshot</parameter>)</function></literal></entry>
17558        <entry><type>setof bigint</type></entry>
17559        <entry>get in-progress transaction IDs in snapshot</entry>
17560       </row>
17561       <row>
17562        <entry><literal><function>txid_snapshot_xmax(<parameter>txid_snapshot</parameter>)</function></literal></entry>
17563        <entry><type>bigint</type></entry>
17564        <entry>get <literal>xmax</literal> of snapshot</entry>
17565       </row>
17566       <row>
17567        <entry><literal><function>txid_snapshot_xmin(<parameter>txid_snapshot</parameter>)</function></literal></entry>
17568        <entry><type>bigint</type></entry>
17569        <entry>get <literal>xmin</literal> of snapshot</entry>
17570       </row>
17571       <row>
17572        <entry><literal><function>txid_visible_in_snapshot(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</function></literal></entry>
17573        <entry><type>boolean</type></entry>
17574        <entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
17575       </row>
17576      </tbody>
17577     </tgroup>
17578    </table>
17579
17580    <para>
17581     The internal transaction ID type (<type>xid</>) is 32 bits wide and
17582     wraps around every 4 billion transactions.  However, these functions
17583     export a 64-bit format that is extended with an <quote>epoch</> counter
17584     so it will not wrap around during the life of an installation.
17585     The data type used by these functions, <type>txid_snapshot</type>,
17586     stores information about transaction ID
17587     visibility at a particular moment in time.  Its components are
17588     described in <xref linkend="functions-txid-snapshot-parts">.
17589    </para>
17590
17591    <table id="functions-txid-snapshot-parts">
17592     <title>Snapshot Components</title>
17593     <tgroup cols="2">
17594      <thead>
17595       <row>
17596        <entry>Name</entry>
17597        <entry>Description</entry>
17598       </row>
17599      </thead>
17600
17601      <tbody>
17602
17603       <row>
17604        <entry><type>xmin</type></entry>
17605        <entry>
17606          Earliest transaction ID (txid) that is still active.  All earlier
17607          transactions will either be committed and visible, or rolled
17608          back and dead.
17609        </entry>
17610       </row>
17611
17612       <row>
17613        <entry><type>xmax</type></entry>
17614        <entry>
17615         First as-yet-unassigned txid.  All txids greater than or equal to this
17616         are not yet started as of the time of the snapshot, and thus invisible.
17617        </entry>
17618       </row>
17619
17620       <row>
17621        <entry><type>xip_list</type></entry>
17622        <entry>
17623         Active txids at the time of the snapshot.  The list
17624         includes only those active txids between <literal>xmin</>
17625         and <literal>xmax</>; there might be active txids higher
17626         than <literal>xmax</>.  A txid that is <literal>xmin &lt;= txid &lt;
17627         xmax</literal> and not in this list was already completed
17628         at the time of the snapshot, and thus either visible or
17629         dead according to its commit status.  The list does not
17630         include txids of subtransactions.
17631        </entry>
17632       </row>
17633
17634      </tbody>
17635     </tgroup>
17636    </table>
17637
17638    <para>
17639     <type>txid_snapshot</>'s textual representation is
17640     <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
17641     For example <literal>10:20:10,14,15</literal> means
17642     <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
17643    </para>
17644
17645    <para>
17646     The functions shown in <xref linkend="functions-commit-timestamp">
17647     provide information about transactions that have been already committed.
17648     These functions mainly provide information about when the transactions
17649     were committed. They only provide useful data when
17650     <xref linkend="guc-track-commit-timestamp"> configuration option is enabled
17651     and only for transactions that were committed after it was enabled.
17652    </para>
17653
17654    <table id="functions-commit-timestamp">
17655     <title>Committed transaction information</title>
17656     <tgroup cols="3">
17657      <thead>
17658       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
17659      </thead>
17660
17661      <tbody>
17662       <row>
17663        <entry>
17664         <indexterm><primary>pg_xact_commit_timestamp</primary></indexterm>
17665         <literal><function>pg_xact_commit_timestamp(<parameter>xid</parameter>)</function></literal>
17666        </entry>
17667        <entry><type>timestamp with time zone</type></entry>
17668        <entry>get commit timestamp of a transaction</entry>
17669       </row>
17670
17671       <row>
17672        <entry>
17673         <indexterm><primary>pg_last_committed_xact</primary></indexterm>
17674         <literal><function>pg_last_committed_xact()</function></literal>
17675        </entry>
17676        <entry><parameter>xid</> <type>xid</>, <parameter>timestamp</> <type>timestamp with time zone</></entry>
17677        <entry>get transaction ID and commit timestamp of latest committed transaction</entry>
17678       </row>
17679      </tbody>
17680     </tgroup>
17681    </table>
17682
17683    <para>
17684     The functions shown in <xref linkend="functions-controldata">
17685     print information initialized during <command>initdb</>, such
17686     as the catalog version. They also show information about write-ahead
17687     logging and checkpoint processing. This information is cluster-wide,
17688     and not specific to any one database. They provide most of the same
17689     information, from the same source, as
17690     <xref linkend="APP-PGCONTROLDATA">, although in a form better suited
17691     to <acronym>SQL</acronym> functions.
17692    </para>
17693
17694    <table id="functions-controldata">
17695     <title>Control Data Functions</title>
17696     <tgroup cols="3">
17697      <thead>
17698       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
17699      </thead>
17700
17701      <tbody>
17702       <row>
17703        <entry>
17704         <indexterm><primary>pg_control_checkpoint</primary></indexterm>
17705         <literal><function>pg_control_checkpoint()</function></literal>
17706        </entry>
17707        <entry><type>record</type></entry>
17708        <entry>
17709         Returns information about current checkpoint state.
17710        </entry>
17711       </row>
17712
17713       <row>
17714        <entry>
17715         <indexterm><primary>pg_control_system</primary></indexterm>
17716         <literal><function>pg_control_system()</function></literal>
17717        </entry>
17718        <entry><type>record</type></entry>
17719        <entry>
17720         Returns information about current control file state.
17721        </entry>
17722       </row>
17723
17724       <row>
17725        <entry>
17726         <indexterm><primary>pg_control_init</primary></indexterm>
17727         <literal><function>pg_control_init()</function></literal>
17728        </entry>
17729        <entry><type>record</type></entry>
17730        <entry>
17731         Returns information about cluster initialization state.
17732        </entry>
17733       </row>
17734
17735       <row>
17736        <entry>
17737         <indexterm><primary>pg_control_recovery</primary></indexterm>
17738         <literal><function>pg_control_recovery()</function></literal>
17739        </entry>
17740        <entry><type>record</type></entry>
17741        <entry>
17742         Returns information about recovery state.
17743        </entry>
17744       </row>
17745
17746      </tbody>
17747     </tgroup>
17748    </table>
17749
17750    <para>
17751     <function>pg_control_checkpoint</> returns a record, shown in
17752     <xref linkend="functions-pg-control-checkpoint">
17753    </para>
17754
17755    <table id="functions-pg-control-checkpoint">
17756     <title><function>pg_control_checkpoint</> Columns</title>
17757     <tgroup cols="2">
17758      <thead>
17759       <row>
17760        <entry>Column Name</entry>
17761        <entry>Data Type</entry>
17762       </row>
17763      </thead>
17764
17765      <tbody>
17766
17767       <row>
17768        <entry><literal>checkpoint_location</literal></entry>
17769        <entry><type>pg_lsn</type></entry>
17770       </row>
17771
17772       <row>
17773        <entry><literal>prior_location</literal></entry>
17774        <entry><type>pg_lsn</type></entry>
17775       </row>
17776
17777       <row>
17778        <entry><literal>redo_location</literal></entry>
17779        <entry><type>pg_lsn</type></entry>
17780       </row>
17781
17782       <row>
17783        <entry><literal>redo_wal_file</literal></entry>
17784        <entry><type>text</type></entry>
17785       </row>
17786
17787       <row>
17788        <entry><literal>timeline_id</literal></entry>
17789        <entry><type>integer</type></entry>
17790       </row>
17791
17792       <row>
17793        <entry><literal>prev_timeline_id</literal></entry>
17794        <entry><type>integer</type></entry>
17795       </row>
17796
17797       <row>
17798        <entry><literal>full_page_writes</literal></entry>
17799        <entry><type>boolean</type></entry>
17800       </row>
17801
17802       <row>
17803        <entry><literal>next_xid</literal></entry>
17804        <entry><type>text</type></entry>
17805       </row>
17806
17807       <row>
17808        <entry><literal>next_oid</literal></entry>
17809        <entry><type>oid</type></entry>
17810       </row>
17811
17812       <row>
17813        <entry><literal>next_multixact_id</literal></entry>
17814        <entry><type>xid</type></entry>
17815       </row>
17816
17817       <row>
17818        <entry><literal>next_multi_offset</literal></entry>
17819        <entry><type>xid</type></entry>
17820       </row>
17821
17822       <row>
17823        <entry><literal>oldest_xid</literal></entry>
17824        <entry><type>xid</type></entry>
17825       </row>
17826
17827       <row>
17828        <entry><literal>oldest_xid_dbid</literal></entry>
17829        <entry><type>oid</type></entry>
17830       </row>
17831
17832       <row>
17833        <entry><literal>oldest_active_xid</literal></entry>
17834        <entry><type>xid</type></entry>
17835       </row>
17836
17837       <row>
17838        <entry><literal>oldest_multi_xid</literal></entry>
17839        <entry><type>xid</type></entry>
17840       </row>
17841
17842       <row>
17843        <entry><literal>oldest_multi_dbid</literal></entry>
17844        <entry><type>oid</type></entry>
17845       </row>
17846
17847       <row>
17848        <entry><literal>oldest_commit_ts_xid</literal></entry>
17849        <entry><type>xid</type></entry>
17850       </row>
17851
17852       <row>
17853        <entry><literal>newest_commit_ts_xid</literal></entry>
17854        <entry><type>xid</type></entry>
17855       </row>
17856
17857       <row>
17858        <entry><literal>checkpoint_time</literal></entry>
17859        <entry><type>timestamp with time zone</type></entry>
17860       </row>
17861
17862      </tbody>
17863     </tgroup>
17864    </table>
17865
17866    <para>
17867     <function>pg_control_system</> returns a record, shown in
17868     <xref linkend="functions-pg-control-system">
17869    </para>
17870
17871    <table id="functions-pg-control-system">
17872     <title><function>pg_control_system</> Columns</title>
17873     <tgroup cols="2">
17874      <thead>
17875       <row>
17876        <entry>Column Name</entry>
17877        <entry>Data Type</entry>
17878       </row>
17879      </thead>
17880
17881      <tbody>
17882
17883       <row>
17884        <entry><literal>pg_control_version</literal></entry>
17885        <entry><type>integer</type></entry>
17886       </row>
17887
17888       <row>
17889        <entry><literal>catalog_version_no</literal></entry>
17890        <entry><type>integer</type></entry>
17891       </row>
17892
17893       <row>
17894        <entry><literal>system_identifier</literal></entry>
17895        <entry><type>bigint</type></entry>
17896       </row>
17897
17898       <row>
17899        <entry><literal>pg_control_last_modified</literal></entry>
17900        <entry><type>timestamp with time zone</type></entry>
17901       </row>
17902
17903      </tbody>
17904     </tgroup>
17905    </table>
17906
17907    <para>
17908     <function>pg_control_init</> returns a record, shown in
17909     <xref linkend="functions-pg-control-init">
17910    </para>
17911
17912    <table id="functions-pg-control-init">
17913     <title><function>pg_control_init</> Columns</title>
17914     <tgroup cols="2">
17915      <thead>
17916       <row>
17917        <entry>Column Name</entry>
17918        <entry>Data Type</entry>
17919       </row>
17920      </thead>
17921
17922      <tbody>
17923
17924       <row>
17925        <entry><literal>max_data_alignment</literal></entry>
17926        <entry><type>integer</type></entry>
17927       </row>
17928
17929       <row>
17930        <entry><literal>database_block_size</literal></entry>
17931        <entry><type>integer</type></entry>
17932       </row>
17933
17934       <row>
17935        <entry><literal>blocks_per_segment</literal></entry>
17936        <entry><type>integer</type></entry>
17937       </row>
17938
17939       <row>
17940        <entry><literal>wal_block_size</literal></entry>
17941        <entry><type>integer</type></entry>
17942       </row>
17943
17944       <row>
17945        <entry><literal>bytes_per_wal_segment</literal></entry>
17946        <entry><type>integer</type></entry>
17947       </row>
17948
17949       <row>
17950        <entry><literal>max_identifier_length</literal></entry>
17951        <entry><type>integer</type></entry>
17952       </row>
17953
17954       <row>
17955        <entry><literal>max_index_columns</literal></entry>
17956        <entry><type>integer</type></entry>
17957       </row>
17958
17959       <row>
17960        <entry><literal>max_toast_chunk_size</literal></entry>
17961        <entry><type>integer</type></entry>
17962       </row>
17963
17964       <row>
17965        <entry><literal>large_object_chunk_size</literal></entry>
17966        <entry><type>integer</type></entry>
17967       </row>
17968
17969       <row>
17970        <entry><literal>float4_pass_by_value</literal></entry>
17971        <entry><type>boolean</type></entry>
17972       </row>
17973
17974       <row>
17975        <entry><literal>float8_pass_by_value</literal></entry>
17976        <entry><type>boolean</type></entry>
17977       </row>
17978
17979       <row>
17980        <entry><literal>data_page_checksum_version</literal></entry>
17981        <entry><type>integer</type></entry>
17982       </row>
17983
17984      </tbody>
17985     </tgroup>
17986    </table>
17987
17988    <para>
17989     <function>pg_control_recovery</> returns a record, shown in
17990     <xref linkend="functions-pg-control-recovery">
17991    </para>
17992
17993    <table id="functions-pg-control-recovery">
17994     <title><function>pg_control_recovery</> Columns</title>
17995     <tgroup cols="2">
17996      <thead>
17997       <row>
17998        <entry>Column Name</entry>
17999        <entry>Data Type</entry>
18000       </row>
18001      </thead>
18002
18003      <tbody>
18004
18005       <row>
18006        <entry><literal>min_recovery_end_location</literal></entry>
18007        <entry><type>pg_lsn</type></entry>
18008       </row>
18009
18010       <row>
18011        <entry><literal>min_recovery_end_timeline</literal></entry>
18012        <entry><type>integer</type></entry>
18013       </row>
18014
18015       <row>
18016        <entry><literal>backup_start_location</literal></entry>
18017        <entry><type>pg_lsn</type></entry>
18018       </row>
18019
18020       <row>
18021        <entry><literal>backup_end_location</literal></entry>
18022        <entry><type>pg_lsn</type></entry>
18023       </row>
18024
18025       <row>
18026        <entry><literal>end_of_backup_record_required</literal></entry>
18027        <entry><type>boolean</type></entry>
18028       </row>
18029
18030      </tbody>
18031     </tgroup>
18032    </table>
18033
18034   </sect1>
18035
18036   <sect1 id="functions-admin">
18037    <title>System Administration Functions</title>
18038
18039    <para>
18040     The functions described in this section are used to control and
18041     monitor a <productname>PostgreSQL</> installation.
18042    </para>
18043
18044   <sect2 id="functions-admin-set">
18045    <title>Configuration Settings Functions</title>
18046
18047    <para>
18048     <xref linkend="functions-admin-set-table"> shows the functions
18049     available to query and alter run-time configuration parameters.
18050    </para>
18051
18052    <table id="functions-admin-set-table">
18053     <title>Configuration Settings Functions</title>
18054     <tgroup cols="3">
18055      <thead>
18056       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
18057      </thead>
18058
18059      <tbody>
18060       <row>
18061        <entry>
18062         <indexterm>
18063          <primary>current_setting</primary>
18064         </indexterm>
18065         <literal><function>current_setting(<parameter>setting_name</parameter> [, <parameter>missing_ok</parameter> ])</function></literal>
18066        </entry>
18067        <entry><type>text</type></entry>
18068        <entry>get current value of setting</entry>
18069       </row>
18070       <row>
18071        <entry>
18072         <indexterm>
18073          <primary>set_config</primary>
18074         </indexterm>
18075         <literal><function>set_config(<parameter>setting_name</parameter>,
18076                              <parameter>new_value</parameter>,
18077                              <parameter>is_local</parameter>)</function></literal>
18078        </entry>
18079        <entry><type>text</type></entry>
18080        <entry>set parameter and return new value</entry>
18081       </row>
18082      </tbody>
18083     </tgroup>
18084    </table>
18085
18086    <indexterm>
18087     <primary>SET</primary>
18088    </indexterm>
18089
18090    <indexterm>
18091     <primary>SHOW</primary>
18092    </indexterm>
18093
18094    <indexterm>
18095     <primary>configuration</primary>
18096     <secondary sortas="server">of the server</secondary>
18097     <tertiary>functions</tertiary>
18098    </indexterm>
18099
18100    <para>
18101     The function <function>current_setting</function> yields the
18102     current value of the setting <parameter>setting_name</parameter>.
18103     It corresponds to the <acronym>SQL</acronym> command
18104     <command>SHOW</command>.  An example:
18105 <programlisting>
18106 SELECT current_setting('datestyle');
18107
18108  current_setting
18109 -----------------
18110  ISO, MDY
18111 (1 row)
18112 </programlisting>
18113
18114     If there is no setting named <parameter>setting_name</parameter>,
18115     <function>current_setting</function> throws an error
18116     unless <parameter>missing_ok</parameter> is supplied and is
18117     <literal>true</literal>.
18118    </para>
18119
18120    <para>
18121     <function>set_config</function> sets the parameter
18122     <parameter>setting_name</parameter> to
18123     <parameter>new_value</parameter>.  If
18124     <parameter>is_local</parameter> is <literal>true</literal>, the
18125     new value will only apply to the current transaction. If you want
18126     the new value to apply for the current session, use
18127     <literal>false</literal> instead. The function corresponds to the
18128     SQL command <command>SET</command>. An example:
18129 <programlisting>
18130 SELECT set_config('log_statement_stats', 'off', false);
18131
18132  set_config
18133 ------------
18134  off
18135 (1 row)
18136 </programlisting>
18137    </para>
18138
18139   </sect2>
18140
18141   <sect2 id="functions-admin-signal">
18142    <title>Server Signaling Functions</title>
18143
18144    <indexterm>
18145     <primary>pg_cancel_backend</primary>
18146    </indexterm>
18147    <indexterm>
18148     <primary>pg_reload_conf</primary>
18149    </indexterm>
18150    <indexterm>
18151     <primary>pg_rotate_logfile</primary>
18152    </indexterm>
18153    <indexterm>
18154     <primary>pg_terminate_backend</primary>
18155    </indexterm>
18156
18157    <indexterm>
18158     <primary>signal</primary>
18159     <secondary sortas="backend">backend processes</secondary>
18160    </indexterm>
18161
18162    <para>
18163     The functions shown in <xref
18164     linkend="functions-admin-signal-table"> send control signals to
18165     other server processes.  Use of these functions is restricted to
18166     superusers by default but access may be granted to others using
18167     <command>GRANT</command>, with noted exceptions.
18168    </para>
18169
18170    <table id="functions-admin-signal-table">
18171     <title>Server Signaling Functions</title>
18172     <tgroup cols="3">
18173      <thead>
18174       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
18175       </row>
18176      </thead>
18177
18178      <tbody>
18179       <row>
18180        <entry>
18181         <literal><function>pg_cancel_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
18182         </entry>
18183        <entry><type>boolean</type></entry>
18184        <entry>Cancel a backend's current query.  This is also allowed if the
18185         calling role is a member of the role whose backend is being canceled or
18186         the calling role has been granted <literal>pg_signal_backend</literal>,
18187         however only superusers can cancel superuser backends.
18188         </entry>
18189       </row>
18190       <row>
18191        <entry>
18192         <literal><function>pg_reload_conf()</function></literal>
18193         </entry>
18194        <entry><type>boolean</type></entry>
18195        <entry>Cause server processes to reload their configuration files</entry>
18196       </row>
18197       <row>
18198        <entry>
18199         <literal><function>pg_rotate_logfile()</function></literal>
18200         </entry>
18201        <entry><type>boolean</type></entry>
18202        <entry>Rotate server's log file</entry>
18203       </row>
18204       <row>
18205        <entry>
18206         <literal><function>pg_terminate_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
18207         </entry>
18208        <entry><type>boolean</type></entry>
18209        <entry>Terminate a backend.  This is also allowed if the calling role
18210         is a member of the role whose backend is being terminated or the
18211         calling role has been granted <literal>pg_signal_backend</literal>,
18212         however only superusers can terminate superuser backends.
18213        </entry>
18214       </row>
18215      </tbody>
18216     </tgroup>
18217    </table>
18218
18219    <para>
18220     Each of these functions returns <literal>true</literal> if
18221     successful and <literal>false</literal> otherwise.
18222    </para>
18223
18224    <para>
18225     <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
18226     send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
18227     respectively) to backend processes identified by process ID.
18228     The process ID of an active backend can be found from
18229     the <structfield>pid</structfield> column of the
18230     <structname>pg_stat_activity</structname> view, or by listing the
18231     <command>postgres</command> processes on the server (using
18232     <application>ps</> on Unix or the <application>Task
18233     Manager</> on <productname>Windows</>).
18234     The role of an active backend can be found from the
18235     <structfield>usename</structfield> column of the
18236     <structname>pg_stat_activity</structname> view.
18237    </para>
18238
18239    <para>
18240     <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
18241     to the server, causing configuration files
18242     to be reloaded by all server processes.
18243    </para>
18244
18245    <para>
18246     <function>pg_rotate_logfile</> signals the log-file manager to switch
18247     to a new output file immediately.  This works only when the built-in
18248     log collector is running, since otherwise there is no log-file manager
18249     subprocess.
18250    </para>
18251
18252   </sect2>
18253
18254   <sect2 id="functions-admin-backup">
18255    <title>Backup Control Functions</title>
18256
18257    <indexterm>
18258     <primary>backup</primary>
18259    </indexterm>
18260    <indexterm>
18261     <primary>pg_create_restore_point</primary>
18262    </indexterm>
18263    <indexterm>
18264     <primary>pg_current_wal_flush_location</primary>
18265    </indexterm>
18266    <indexterm>
18267     <primary>pg_current_wal_insert_location</primary>
18268    </indexterm>
18269    <indexterm>
18270     <primary>pg_current_wal_location</primary>
18271    </indexterm>
18272    <indexterm>
18273     <primary>pg_start_backup</primary>
18274    </indexterm>
18275    <indexterm>
18276     <primary>pg_stop_backup</primary>
18277    </indexterm>
18278    <indexterm>
18279     <primary>pg_is_in_backup</primary>
18280    </indexterm>
18281    <indexterm>
18282     <primary>pg_backup_start_time</primary>
18283    </indexterm>
18284    <indexterm>
18285     <primary>pg_switch_wal</primary>
18286    </indexterm>
18287    <indexterm>
18288     <primary>pg_walfile_name</primary>
18289    </indexterm>
18290    <indexterm>
18291     <primary>pg_walfile_name_offset</primary>
18292    </indexterm>
18293    <indexterm>
18294     <primary>pg_wal_location_diff</primary>
18295    </indexterm>
18296
18297    <para>
18298     The functions shown in <xref
18299     linkend="functions-admin-backup-table"> assist in making on-line backups.
18300     These functions cannot be executed during recovery (except
18301     <function>pg_is_in_backup</function>, <function>pg_backup_start_time</function>
18302     and <function>pg_wal_location_diff</function>).
18303    </para>
18304
18305    <table id="functions-admin-backup-table">
18306     <title>Backup Control Functions</title>
18307     <tgroup cols="3">
18308      <thead>
18309       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
18310       </row>
18311      </thead>
18312
18313      <tbody>
18314       <row>
18315        <entry>
18316         <literal><function>pg_create_restore_point(<parameter>name</> <type>text</>)</function></literal>
18317         </entry>
18318        <entry><type>pg_lsn</type></entry>
18319        <entry>Create a named point for performing restore (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
18320       </row>
18321       <row>
18322        <entry>
18323         <literal><function>pg_current_wal_flush_location()</function></literal>
18324         </entry>
18325        <entry><type>pg_lsn</type></entry>
18326        <entry>Get current transaction log flush location</entry>
18327       </row>
18328       <row>
18329        <entry>
18330         <literal><function>pg_current_wal_insert_location()</function></literal>
18331         </entry>
18332        <entry><type>pg_lsn</type></entry>
18333        <entry>Get current transaction log insert location</entry>
18334       </row>
18335       <row>
18336        <entry>
18337         <literal><function>pg_current_wal_location()</function></literal>
18338         </entry>
18339        <entry><type>pg_lsn</type></entry>
18340        <entry>Get current transaction log write location</entry>
18341       </row>
18342       <row>
18343        <entry>
18344         <literal><function>pg_start_backup(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> <optional>, <parameter>exclusive</> <type>boolean</> </optional></optional>)</function></literal>
18345         </entry>
18346        <entry><type>pg_lsn</type></entry>
18347        <entry>Prepare for performing on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
18348       </row>
18349       <row>
18350        <entry>
18351         <literal><function>pg_stop_backup()</function></literal>
18352         </entry>
18353        <entry><type>pg_lsn</type></entry>
18354        <entry>Finish performing exclusive on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
18355       </row>
18356       <row>
18357        <entry>
18358         <literal><function>pg_stop_backup(<parameter>exclusive</> <type>boolean</>)</function></literal>
18359         </entry>
18360        <entry><type>setof record</type></entry>
18361        <entry>Finish performing exclusive or non-exclusive on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
18362       </row>
18363       <row>
18364        <entry>
18365         <literal><function>pg_is_in_backup()</function></literal>
18366         </entry>
18367        <entry><type>bool</type></entry>
18368        <entry>True if an on-line exclusive backup is still in progress.</entry>
18369       </row>
18370       <row>
18371        <entry>
18372         <literal><function>pg_backup_start_time()</function></literal>
18373         </entry>
18374        <entry><type>timestamp with time zone</type></entry>
18375        <entry>Get start time of an on-line exclusive backup in progress.</entry>
18376       </row>
18377       <row>
18378        <entry>
18379         <literal><function>pg_switch_wal()</function></literal>
18380         </entry>
18381        <entry><type>pg_lsn</type></entry>
18382        <entry>Force switch to a new transaction log file (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
18383       </row>
18384       <row>
18385        <entry>
18386         <literal><function>pg_walfile_name(<parameter>location</> <type>pg_lsn</>)</function></literal>
18387         </entry>
18388        <entry><type>text</type></entry>
18389        <entry>Convert transaction log location string to file name</entry>
18390       </row>
18391       <row>
18392        <entry>
18393         <literal><function>pg_walfile_name_offset(<parameter>location</> <type>pg_lsn</>)</function></literal>
18394         </entry>
18395        <entry><type>text</>, <type>integer</></entry>
18396        <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
18397       </row>
18398       <row>
18399        <entry>
18400         <literal><function>pg_wal_location_diff(<parameter>location</> <type>pg_lsn</>, <parameter>location</> <type>pg_lsn</>)</function></literal>
18401        </entry>
18402        <entry><type>numeric</></entry>
18403        <entry>Calculate the difference between two transaction log locations</entry>
18404       </row>
18405      </tbody>
18406     </tgroup>
18407    </table>
18408
18409    <para>
18410     <function>pg_start_backup</> accepts an arbitrary user-defined label for
18411     the backup.  (Typically this would be the name under which the backup dump
18412     file will be stored.) When used in exclusive mode, the function writes a
18413     backup label file (<filename>backup_label</>) and, if there are any links
18414     in the <filename>pg_tblspc/</> directory, a tablespace map file
18415     (<filename>tablespace_map</>) into the database cluster's data directory,
18416     performs a checkpoint, and then returns the backup's starting transaction
18417     log location as text.  The user can ignore this result value, but it is
18418     provided in case it is useful. When used in non-exclusive mode, the
18419     contents of these files are instead returned by the
18420     <function>pg_stop_backup</> function, and should be written to the backup
18421     by the caller.
18422
18423 <programlisting>
18424 postgres=# select pg_start_backup('label_goes_here');
18425  pg_start_backup
18426 -----------------
18427  0/D4445B8
18428 (1 row)
18429 </programlisting>
18430     There is an optional second parameter of type <type>boolean</type>.  If <literal>true</>,
18431     it specifies executing <function>pg_start_backup</> as quickly as
18432     possible.  This forces an immediate checkpoint which will cause a
18433     spike in I/O operations, slowing any concurrently executing queries.
18434    </para>
18435
18436    <para>
18437     In an exclusive backup, <function>pg_stop_backup</> removes the label file
18438     and, if it exists, the <filename>tablespace_map</> file created by
18439     <function>pg_start_backup</>. In a non-exclusive backup, the contents of
18440     the <filename>backup_label</> and <filename>tablespace_map</> are returned
18441     in the result of the function, and should be written to files in the
18442     backup (and not in the data directory).
18443    </para>
18444
18445    <para>
18446     The function also creates a backup history file in the transaction log
18447     archive area. The history file includes the label given to
18448     <function>pg_start_backup</>, the starting and ending transaction log locations for
18449     the backup, and the starting and ending times of the backup.  The return
18450     value is the backup's ending transaction log location (which again
18451     can be ignored).  After recording the ending location, the current
18452     transaction log insertion
18453     point is automatically advanced to the next transaction log file, so that the
18454     ending transaction log file can be archived immediately to complete the backup.
18455    </para>
18456
18457    <para>
18458     <function>pg_switch_wal</> moves to the next transaction log file, allowing the
18459     current file to be archived (assuming you are using continuous archiving).
18460     The return value is the ending transaction log location + 1 within the just-completed transaction log file.
18461     If there has been no transaction log activity since the last transaction log switch,
18462     <function>pg_switch_wal</> does nothing and returns the start location
18463     of the transaction log file currently in use.
18464    </para>
18465
18466    <para>
18467     <function>pg_create_restore_point</> creates a named transaction log
18468     record that can be used as recovery target, and returns the corresponding
18469     transaction log location.  The given name can then be used with
18470     <xref linkend="recovery-target-name"> to specify the point up to which
18471     recovery will proceed.  Avoid creating multiple restore points with the
18472     same name, since recovery will stop at the first one whose name matches
18473     the recovery target.
18474    </para>
18475
18476    <para>
18477     <function>pg_current_wal_location</> displays the current transaction log write
18478     location in the same format used by the above functions.  Similarly,
18479     <function>pg_current_wal_insert_location</> displays the current transaction log
18480     insertion point and <function>pg_current_wal_flush_location</> displays the
18481     current transaction log flush point. The insertion point is the <quote>logical</>
18482     end of the transaction log at any instant, while the write location is the end of
18483     what has actually been written out from the server's internal buffers and flush
18484     location is the location guaranteed to be written to durable storage. The write
18485     location is the end of what can be examined from outside the server, and is usually
18486     what you want if you are interested in archiving partially-complete transaction log
18487     files.  The insertion and flush points are made available primarily for server
18488     debugging purposes.  These are both read-only operations and do not
18489     require superuser permissions.
18490    </para>
18491
18492    <para>
18493     You can use <function>pg_walfile_name_offset</> to extract the
18494     corresponding transaction log file name and byte offset from the results of any of the
18495     above functions.  For example:
18496 <programlisting>
18497 postgres=# SELECT * FROM pg_walfile_name_offset(pg_stop_backup());
18498         file_name         | file_offset 
18499 --------------------------+-------------
18500  00000001000000000000000D |     4039624
18501 (1 row)
18502 </programlisting>
18503     Similarly, <function>pg_walfile_name</> extracts just the transaction log file name.
18504     When the given transaction log location is exactly at a transaction log file boundary, both
18505     these functions return the name of the preceding transaction log file.
18506     This is usually the desired behavior for managing transaction log archiving
18507     behavior, since the preceding file is the last one that currently
18508     needs to be archived.
18509    </para>
18510
18511    <para>
18512     <function>pg_wal_location_diff</> calculates the difference in bytes
18513     between two transaction log locations. It can be used with
18514     <structname>pg_stat_replication</structname> or some functions shown in
18515     <xref linkend="functions-admin-backup-table"> to get the replication lag.
18516    </para>
18517
18518    <para>
18519     For details about proper usage of these functions, see
18520     <xref linkend="continuous-archiving">.
18521    </para>
18522
18523   </sect2>
18524
18525   <sect2 id="functions-recovery-control">
18526    <title>Recovery Control Functions</title>
18527
18528    <indexterm>
18529     <primary>pg_is_in_recovery</primary>
18530    </indexterm>
18531    <indexterm>
18532     <primary>pg_last_wal_receive_location</primary>
18533    </indexterm>
18534    <indexterm>
18535     <primary>pg_last_wal_replay_location</primary>
18536    </indexterm>
18537    <indexterm>
18538     <primary>pg_last_xact_replay_timestamp</primary>
18539    </indexterm>
18540
18541    <para>
18542     The functions shown in <xref
18543     linkend="functions-recovery-info-table"> provide information
18544     about the current status of the standby.
18545     These functions may be executed both during recovery and in normal running.
18546    </para>
18547
18548    <table id="functions-recovery-info-table">
18549     <title>Recovery Information Functions</title>
18550     <tgroup cols="3">
18551      <thead>
18552       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
18553       </row>
18554      </thead>
18555
18556      <tbody>
18557       <row>
18558        <entry>
18559         <literal><function>pg_is_in_recovery()</function></literal>
18560         </entry>
18561        <entry><type>bool</type></entry>
18562        <entry>True if recovery is still in progress.
18563        </entry>
18564       </row>
18565       <row>
18566        <entry>
18567         <literal><function>pg_last_wal_receive_location()</function></literal>
18568         </entry>
18569        <entry><type>pg_lsn</type></entry>
18570        <entry>Get last transaction log location received and synced to disk by
18571         streaming replication. While streaming replication is in progress
18572         this will increase monotonically. If recovery has completed this will
18573         remain static at
18574         the value of the last WAL record received and synced to disk during
18575         recovery. If streaming replication is disabled, or if it has not yet
18576         started, the function returns NULL.
18577        </entry>
18578       </row>
18579       <row>
18580        <entry>
18581         <literal><function>pg_last_wal_replay_location()</function></literal>
18582         </entry>
18583        <entry><type>pg_lsn</type></entry>
18584        <entry>Get last transaction log location replayed during recovery.
18585         If recovery is still in progress this will increase monotonically.
18586         If recovery has completed then this value will remain static at
18587         the value of the last WAL record applied during that recovery.
18588         When the server has been started normally without recovery
18589         the function returns NULL.
18590        </entry>
18591       </row>
18592       <row>
18593        <entry>
18594         <literal><function>pg_last_xact_replay_timestamp()</function></literal>
18595         </entry>
18596        <entry><type>timestamp with time zone</type></entry>
18597        <entry>Get time stamp of last transaction replayed during recovery.
18598         This is the time at which the commit or abort WAL record for that
18599         transaction was generated on the primary.
18600         If no transactions have been replayed during recovery, this function
18601         returns NULL.  Otherwise, if recovery is still in progress this will
18602         increase monotonically.  If recovery has completed then this value will
18603         remain static at the value of the last transaction applied during that
18604         recovery.  When the server has been started normally without recovery
18605         the function returns NULL.
18606        </entry>
18607       </row>
18608      </tbody>
18609     </tgroup>
18610    </table>
18611
18612    <indexterm>
18613     <primary>pg_is_wal_replay_paused</primary>
18614    </indexterm>
18615    <indexterm>
18616     <primary>pg_wal_replay_pause</primary>
18617    </indexterm>
18618    <indexterm>
18619     <primary>pg_wal_replay_resume</primary>
18620    </indexterm>
18621
18622    <para>
18623     The functions shown in <xref
18624     linkend="functions-recovery-control-table"> control the progress of recovery.
18625     These functions may be executed only during recovery.
18626    </para>
18627
18628    <table id="functions-recovery-control-table">
18629     <title>Recovery Control Functions</title>
18630     <tgroup cols="3">
18631      <thead>
18632       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
18633       </row>
18634      </thead>
18635
18636      <tbody>
18637       <row>
18638        <entry>
18639         <literal><function>pg_is_wal_replay_paused()</function></literal>
18640         </entry>
18641        <entry><type>bool</type></entry>
18642        <entry>True if recovery is paused.
18643        </entry>
18644       </row>
18645       <row>
18646        <entry>
18647         <literal><function>pg_wal_replay_pause()</function></literal>
18648         </entry>
18649        <entry><type>void</type></entry>
18650        <entry>Pauses recovery immediately (restricted to superusers by default, but other users can be granted EXECUTE to run the function).
18651        </entry>
18652       </row>
18653       <row>
18654        <entry>
18655         <literal><function>pg_wal_replay_resume()</function></literal>
18656         </entry>
18657        <entry><type>void</type></entry>
18658        <entry>Restarts recovery if it was paused (restricted to superusers by default, but other users can be granted EXECUTE to run the function).
18659        </entry>
18660       </row>
18661      </tbody>
18662     </tgroup>
18663    </table>
18664
18665    <para>
18666     While recovery is paused no further database changes are applied.
18667     If in hot standby, all new queries will see the same consistent snapshot
18668     of the database, and no further query conflicts will be generated until
18669     recovery is resumed.
18670    </para>
18671
18672    <para>
18673     If streaming replication is disabled, the paused state may continue
18674     indefinitely without problem. While streaming replication is in
18675     progress WAL records will continue to be received, which will
18676     eventually fill available disk space, depending upon the duration of
18677     the pause, the rate of WAL generation and available disk space.
18678    </para>
18679
18680   </sect2>
18681
18682   <sect2 id="functions-snapshot-synchronization">
18683    <title>Snapshot Synchronization Functions</title>
18684
18685    <indexterm>
18686      <primary>pg_export_snapshot</primary>
18687    </indexterm>
18688
18689    <para>
18690     <productname>PostgreSQL</> allows database sessions to synchronize their
18691     snapshots. A <firstterm>snapshot</> determines which data is visible to the
18692     transaction that is using the snapshot. Synchronized snapshots are
18693     necessary when two or more sessions need to see identical content in the
18694     database. If two sessions just start their transactions independently,
18695     there is always a possibility that some third transaction commits
18696     between the executions of the two <command>START TRANSACTION</> commands,
18697     so that one session sees the effects of that transaction and the other
18698     does not.
18699    </para>
18700
18701    <para>
18702     To solve this problem, <productname>PostgreSQL</> allows a transaction to
18703     <firstterm>export</> the snapshot it is using.  As long as the exporting
18704     transaction remains open, other transactions can <firstterm>import</> its
18705     snapshot, and thereby be guaranteed that they see exactly the same view
18706     of the database that the first transaction sees.  But note that any
18707     database changes made by any one of these transactions remain invisible
18708     to the other transactions, as is usual for changes made by uncommitted
18709     transactions.  So the transactions are synchronized with respect to
18710     pre-existing data, but act normally for changes they make themselves.
18711    </para>
18712
18713    <para>
18714     Snapshots are exported with the <function>pg_export_snapshot</> function,
18715     shown in <xref linkend="functions-snapshot-synchronization-table">, and
18716     imported with the <xref linkend="sql-set-transaction"> command.
18717    </para>
18718
18719    <table id="functions-snapshot-synchronization-table">
18720     <title>Snapshot Synchronization Functions</title>
18721     <tgroup cols="3">
18722      <thead>
18723       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
18724       </row>
18725      </thead>
18726
18727      <tbody>
18728       <row>
18729        <entry>
18730         <literal><function>pg_export_snapshot()</function></literal>
18731        </entry>
18732        <entry><type>text</type></entry>
18733        <entry>Save the current snapshot and return its identifier</entry>
18734       </row>
18735      </tbody>
18736     </tgroup>
18737    </table>
18738
18739    <para>
18740     The function <function>pg_export_snapshot</> saves the current snapshot
18741     and returns a <type>text</> string identifying the snapshot.  This string
18742     must be passed (outside the database) to clients that want to import the
18743     snapshot.  The snapshot is available for import only until the end of the
18744     transaction that exported it.  A transaction can export more than one
18745     snapshot, if needed.  Note that doing so is only useful in <literal>READ
18746     COMMITTED</> transactions, since in <literal>REPEATABLE READ</> and
18747     higher isolation levels, transactions use the same snapshot throughout
18748     their lifetime.  Once a transaction has exported any snapshots, it cannot
18749     be prepared with <xref linkend="sql-prepare-transaction">.
18750    </para>
18751
18752    <para>
18753     See  <xref linkend="sql-set-transaction"> for details of how to use an
18754     exported snapshot.
18755    </para>
18756   </sect2>
18757
18758   <sect2 id="functions-replication">
18759    <title>Replication Functions</title>
18760
18761    <para>
18762     The functions shown
18763     in <xref linkend="functions-replication-table"> are for
18764     controlling and interacting with replication features.
18765     See <xref linkend="streaming-replication">,
18766     <xref linkend="streaming-replication-slots">, and
18767     <xref linkend="replication-origins">
18768     for information about the underlying features.  Use of these
18769     functions is restricted to superusers.
18770    </para>
18771
18772    <para>
18773     Many of these functions have equivalent commands in the replication
18774     protocol; see <xref linkend="protocol-replication">.
18775    </para>
18776
18777    <para>
18778     The functions described in
18779     <xref linkend="functions-admin-backup">,
18780     <xref linkend="functions-recovery-control">, and
18781     <xref linkend="functions-snapshot-synchronization">
18782     are also relevant for replication.
18783    </para>
18784
18785    <table id="functions-replication-table">
18786     <title>Replication <acronym>SQL</acronym> Functions</title>
18787     <tgroup cols="3">
18788      <thead>
18789       <row>
18790        <entry>Function</entry>
18791        <entry>Return Type</entry>
18792        <entry>Description</entry>
18793       </row>
18794      </thead>
18795      <tbody>
18796       <row>
18797        <entry>
18798         <indexterm>
18799          <primary>pg_create_physical_replication_slot</primary>
18800         </indexterm>
18801         <literal><function>pg_create_physical_replication_slot(<parameter>slot_name</parameter> <type>name</type> <optional>, <parameter>immediately_reserve</> <type>boolean</>, <parameter>temporary</> <type>boolean</></optional>)</function></literal>
18802        </entry>
18803        <entry>
18804         (<parameter>slot_name</parameter> <type>name</type>, <parameter>wal_position</parameter> <type>pg_lsn</type>)
18805        </entry>
18806        <entry>
18807         Creates a new physical replication slot named
18808         <parameter>slot_name</parameter>. The optional second parameter,
18809         when <literal>true</>, specifies that the <acronym>LSN</> for this
18810         replication slot be reserved immediately; otherwise
18811         the <acronym>LSN</> is reserved on first connection from a streaming
18812         replication client. Streaming changes from a physical slot is only
18813         possible with the streaming-replication protocol &mdash;
18814         see <xref linkend="protocol-replication">. The optional third
18815         parameter, <parameter>temporary</>, when set to true, specifies that
18816         the slot should not be permanently stored to disk and is only meant
18817         for use by current session. Temporary slots are also
18818         released upon any error. This function corresponds
18819         to the replication protocol command <literal>CREATE_REPLICATION_SLOT
18820         ... PHYSICAL</literal>.
18821        </entry>
18822       </row>
18823       <row>
18824        <entry>
18825         <indexterm>
18826          <primary>pg_drop_replication_slot</primary>
18827         </indexterm>
18828         <literal><function>pg_drop_replication_slot(<parameter>slot_name</parameter> <type>name</type>)</function></literal>
18829        </entry>
18830        <entry>
18831         <type>void</type>
18832        </entry>
18833        <entry>
18834         Drops the physical or logical replication slot
18835         named <parameter>slot_name</parameter>. Same as replication protocol
18836         command <literal>DROP_REPLICATION_SLOT</>.
18837        </entry>
18838       </row>
18839
18840       <row>
18841        <entry>
18842         <indexterm>
18843          <primary>pg_create_logical_replication_slot</primary>
18844         </indexterm>
18845         <literal><function>pg_create_logical_replication_slot(<parameter>slot_name</parameter> <type>name</type>, <parameter>plugin</parameter> <type>name</type> <optional>, <parameter>temporary</> <type>boolean</></optional>)</function></literal>
18846        </entry>
18847        <entry>
18848         (<parameter>slot_name</parameter> <type>name</type>, <parameter>wal_position</parameter> <type>pg_lsn</type>)
18849        </entry>
18850        <entry>
18851         Creates a new logical (decoding) replication slot named
18852         <parameter>slot_name</parameter> using the output plugin
18853         <parameter>plugin</parameter>. The optional third
18854         parameter, <parameter>temporary</>, when set to true, specifies that
18855         the slot should not be permanently stored to disk and is only meant
18856         for use by current session. Temporary slots are also
18857         released upon any error. A call to this function has the same
18858         effect as the replication protocol command
18859         <literal>CREATE_REPLICATION_SLOT ... LOGICAL</literal>.
18860        </entry>
18861       </row>
18862
18863       <row>
18864        <entry>
18865         <indexterm>
18866          <primary>pg_logical_slot_get_changes</primary>
18867         </indexterm>
18868         <literal><function>pg_logical_slot_get_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
18869        </entry>
18870        <entry>
18871         (<parameter>location</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>text</type>)
18872        </entry>
18873        <entry>
18874         Returns changes in the slot <parameter>slot_name</parameter>, starting
18875         from the point at which since changes have been consumed last.  If
18876         <parameter>upto_lsn</> and <parameter>upto_nchanges</> are NULL,
18877         logical decoding will continue until end of WAL.  If
18878         <parameter>upto_lsn</> is non-NULL, decoding will include only
18879         those transactions which commit prior to the specified LSN.  If
18880         <parameter>upto_nchanges</parameter> is non-NULL, decoding will
18881         stop when the number of rows produced by decoding exceeds
18882         the specified value.  Note, however, that the actual number of
18883         rows returned may be larger, since this limit is only checked after
18884         adding the rows produced when decoding each new transaction commit.
18885        </entry>
18886       </row>
18887
18888       <row>
18889        <entry>
18890         <indexterm>
18891          <primary>pg_logical_slot_peek_changes</primary>
18892         </indexterm>
18893         <literal><function>pg_logical_slot_peek_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
18894        </entry>
18895        <entry>
18896         (<parameter>location</parameter> <type>text</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>text</type>)
18897        </entry>
18898        <entry>
18899         Behaves just like
18900         the <function>pg_logical_slot_get_changes()</function> function,
18901         except that changes are not consumed; that is, they will be returned
18902         again on future calls.
18903        </entry>
18904       </row>
18905
18906       <row>
18907        <entry>
18908         <indexterm>
18909          <primary>pg_logical_slot_get_binary_changes</primary>
18910         </indexterm>
18911         <literal><function>pg_logical_slot_get_binary_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
18912        </entry>
18913        <entry>
18914         (<parameter>location</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>bytea</type>)
18915        </entry>
18916        <entry>
18917         Behaves just like
18918         the <function>pg_logical_slot_get_changes()</function> function,
18919         except that changes are returned as <type>bytea</type>.
18920        </entry>
18921       </row>
18922
18923       <row>
18924        <entry>
18925         <indexterm>
18926          <primary>pg_logical_slot_peek_binary_changes</primary>
18927         </indexterm>
18928         <literal><function>pg_logical_slot_peek_binary_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
18929        </entry>
18930        <entry>
18931         (<parameter>location</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>bytea</type>)
18932        </entry>
18933        <entry>
18934         Behaves just like
18935         the <function>pg_logical_slot_get_changes()</function> function,
18936         except that changes are returned as <type>bytea</type> and that
18937         changes are not consumed; that is, they will be returned again
18938         on future calls.
18939        </entry>
18940       </row>
18941
18942       <row>
18943        <entry id="pg-replication-origin-create">
18944         <indexterm>
18945          <primary>pg_replication_origin_create</primary>
18946         </indexterm>
18947         <literal><function>pg_replication_origin_create(<parameter>node_name</parameter> <type>text</type>)</function></literal>
18948        </entry>
18949        <entry>
18950         <type>oid</type>
18951        </entry>
18952        <entry>
18953         Create a replication origin with the given external
18954         name, and return the internal id assigned to it.
18955        </entry>
18956       </row>
18957
18958       <row>
18959        <entry id="pg-replication-origin-drop">
18960         <indexterm>
18961          <primary>pg_replication_origin_drop</primary>
18962         </indexterm>
18963         <literal><function>pg_replication_origin_drop(<parameter>node_name</parameter> <type>text</type>)</function></literal>
18964        </entry>
18965        <entry>
18966         <type>void</>
18967        </entry>
18968        <entry>
18969         Delete a previously created replication origin, including any
18970         associated replay progress.
18971        </entry>
18972       </row>
18973
18974       <row>
18975        <entry>
18976         <indexterm>
18977          <primary>pg_replication_origin_oid</primary>
18978         </indexterm>
18979         <literal><function>pg_replication_origin_oid(<parameter>node_name</parameter> <type>text</type>)</function></literal>
18980        </entry>
18981        <entry>
18982         <type>oid</type>
18983        </entry>
18984        <entry>
18985         Lookup a replication origin by name and return the internal id. If no
18986         corresponding replication origin is found an error is thrown.
18987        </entry>
18988       </row>
18989
18990       <row>
18991        <entry id="pg-replication-origin-session-setup">
18992         <indexterm>
18993          <primary>pg_replication_origin_session_setup</primary>
18994         </indexterm>
18995         <literal><function>pg_replication_origin_session_setup(<parameter>node_name</parameter> <type>text</type>)</function></literal>
18996        </entry>
18997        <entry>
18998         <type>void</>
18999        </entry>
19000        <entry>
19001         Mark the current session as replaying from the given
19002         origin, allowing replay progress to be tracked.  Use
19003         <function>pg_replication_origin_session_reset</function> to revert.
19004         Can only be used if no previous origin is configured.
19005        </entry>
19006       </row>
19007
19008       <row>
19009        <entry>
19010         <indexterm>
19011          <primary>pg_replication_origin_session_reset</primary>
19012         </indexterm>
19013         <literal><function>pg_replication_origin_session_reset()</function></literal>
19014        </entry>
19015        <entry>
19016         <type>void</>
19017        </entry>
19018        <entry>
19019         Cancel the effects
19020         of <function>pg_replication_origin_session_setup()</function>.
19021        </entry>
19022       </row>
19023
19024       <row>
19025        <entry>
19026         <indexterm>
19027          <primary>pg_replication_origin_session_is_setup</primary>
19028         </indexterm>
19029         <literal><function>pg_replication_origin_session_is_setup()</function></literal>
19030        </entry>
19031        <entry>
19032         <type>bool</type>
19033        </entry>
19034        <entry>
19035         Has a replication origin been configured in the current session?
19036        </entry>
19037       </row>
19038
19039       <row>
19040        <entry id="pg-replication-origin-session-progress">
19041         <indexterm>
19042          <primary>pg_replication_origin_session_progress</primary>
19043         </indexterm>
19044         <literal><function>pg_replication_origin_session_progress(<parameter>flush</parameter> <type>bool</type>)</function></literal>
19045        </entry>
19046        <entry>
19047         <type>pg_lsn</type>
19048        </entry>
19049        <entry>
19050         Return the replay position for the replication origin configured in
19051         the current session. The parameter <parameter>flush</parameter>
19052         determines whether the corresponding local transaction will be
19053         guaranteed to have been flushed to disk or not.
19054        </entry>
19055       </row>
19056
19057       <row>
19058        <entry id="pg-replication-origin-xact-setup">
19059         <indexterm>
19060          <primary>pg_replication_origin_xact_setup</primary>
19061         </indexterm>
19062         <literal><function>pg_replication_origin_xact_setup(<parameter>origin_lsn</parameter> <type>pg_lsn</type>, <parameter>origin_timestamp</parameter> <type>timestamptz</type>)</function></literal>
19063        </entry>
19064        <entry>
19065         <type>void</>
19066        </entry>
19067        <entry>
19068         Mark the current transaction as replaying a transaction that has
19069         committed at the given <acronym>LSN</acronym> and timestamp. Can
19070         only be called when a replication origin has previously been
19071         configured using
19072         <function>pg_replication_origin_session_setup()</function>.
19073        </entry>
19074       </row>
19075
19076       <row>
19077        <entry id="pg-replication-origin-xact-reset">
19078         <indexterm>
19079          <primary>pg_replication_origin_xact_reset</primary>
19080         </indexterm>
19081         <literal><function>pg_replication_origin_xact_reset()</function></literal>
19082        </entry>
19083        <entry>
19084         <type>void</>
19085        </entry>
19086        <entry>
19087         Cancel the effects of
19088         <function>pg_replication_origin_xact_setup()</function>.
19089        </entry>
19090       </row>
19091
19092       <row>
19093        <entry id="pg-replication-origin-advance">
19094         <indexterm>
19095          <primary>pg_replication_origin_advance</primary>
19096         </indexterm>
19097         <literal>pg_replication_origin_advance<function>(<parameter>node_name</parameter> <type>text</type>, <parameter>pos</parameter> <type>pg_lsn</type>)</function></literal>
19098        </entry>
19099        <entry>
19100         <type>void</>
19101        </entry>
19102        <entry>
19103         Set replication progress for the given node to the given
19104         position. This primarily is useful for setting up the initial position
19105         or a new position after configuration changes and similar. Be aware
19106         that careless use of this function can lead to inconsistently
19107         replicated data.
19108        </entry>
19109       </row>
19110
19111       <row>
19112        <entry id="pg-replication-origin-progress">
19113         <indexterm>
19114          <primary>pg_replication_origin_progress</primary>
19115         </indexterm>
19116         <literal><function>pg_replication_origin_progress(<parameter>node_name</parameter> <type>text</type>, <parameter>flush</parameter> <type>bool</type>)</function></literal>
19117        </entry>
19118        <entry>
19119         <type>pg_lsn</type>
19120        </entry>
19121        <entry>
19122         Return the replay position for the given replication origin. The
19123         parameter <parameter>flush</parameter> determines whether the
19124         corresponding local transaction will be guaranteed to have been
19125         flushed to disk or not.
19126        </entry>
19127       </row>
19128
19129       <row>
19130        <entry id="pg-logical-emit-message-text">
19131         <indexterm>
19132          <primary>pg_logical_emit_message</primary>
19133         </indexterm>
19134         <literal><function>pg_logical_emit_message(<parameter>transactional</parameter> <type>bool</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>text</type>)</function></literal>
19135        </entry>
19136        <entry>
19137         <type>pg_lsn</type>
19138        </entry>
19139        <entry>
19140         Emit text logical decoding message. This can be used to pass generic
19141         messages to logical decoding plugins through WAL. The parameter
19142         <parameter>transactional</parameter> specifies if the message should
19143         be part of current transaction or if it should be written immediately
19144         and decoded as soon as the logical decoding reads the record. The
19145         <parameter>prefix</parameter> is textual prefix used by the logical
19146         decoding plugins to easily recognize interesting messages for them.
19147         The <parameter>content</parameter> is the text of the message.
19148        </entry>
19149       </row>
19150
19151       <row>
19152        <entry id="pg-logical-emit-message-bytea">
19153         <literal><function>pg_logical_emit_message(<parameter>transactional</parameter> <type>bool</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>bytea</type>)</function></literal>
19154        </entry>
19155        <entry>
19156         <type>pg_lsn</type>
19157        </entry>
19158        <entry>
19159         Emit binary logical decoding message. This can be used to pass generic
19160         messages to logical decoding plugins through WAL. The parameter
19161         <parameter>transactional</parameter> specifies if the message should
19162         be part of current transaction or if it should be written immediately
19163         and decoded as soon as the logical decoding reads the record. The
19164         <parameter>prefix</parameter> is textual prefix used by the logical
19165         decoding plugins to easily recognize interesting messages for them.
19166         The <parameter>content</parameter> is the binary content of the
19167         message.
19168        </entry>
19169       </row>
19170
19171      </tbody>
19172     </tgroup>
19173    </table>
19174
19175   </sect2>
19176
19177   <sect2 id="functions-admin-dbobject">
19178    <title>Database Object Management Functions</title>
19179
19180    <para>
19181     The functions shown in <xref linkend="functions-admin-dbsize"> calculate
19182     the disk space usage of database objects.
19183    </para>
19184
19185    <indexterm>
19186     <primary>pg_column_size</primary>
19187    </indexterm>
19188    <indexterm>
19189     <primary>pg_database_size</primary>
19190    </indexterm>
19191    <indexterm>
19192     <primary>pg_indexes_size</primary>
19193    </indexterm>
19194    <indexterm>
19195     <primary>pg_relation_size</primary>
19196    </indexterm>
19197    <indexterm>
19198     <primary>pg_size_bytes</primary>
19199    </indexterm>
19200    <indexterm>
19201     <primary>pg_size_pretty</primary>
19202    </indexterm>
19203    <indexterm>
19204     <primary>pg_table_size</primary>
19205    </indexterm>
19206    <indexterm>
19207     <primary>pg_tablespace_size</primary>
19208    </indexterm>
19209    <indexterm>
19210     <primary>pg_total_relation_size</primary>
19211    </indexterm>
19212
19213    <table id="functions-admin-dbsize">
19214     <title>Database Object Size Functions</title>
19215     <tgroup cols="3">
19216      <thead>
19217       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
19218       </row>
19219      </thead>
19220
19221      <tbody>
19222       <row>
19223        <entry><literal><function>pg_column_size(<type>any</type>)</function></literal></entry>
19224        <entry><type>int</type></entry>
19225        <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
19226       </row>
19227       <row>
19228        <entry>
19229         <literal><function>pg_database_size(<type>oid</type>)</function></literal>
19230         </entry>
19231        <entry><type>bigint</type></entry>
19232        <entry>Disk space used by the database with the specified OID</entry>
19233       </row>
19234       <row>
19235        <entry>
19236         <literal><function>pg_database_size(<type>name</type>)</function></literal>
19237         </entry>
19238        <entry><type>bigint</type></entry>
19239        <entry>Disk space used by the database with the specified name</entry>
19240       </row>
19241       <row>
19242        <entry>
19243         <literal><function>pg_indexes_size(<type>regclass</type>)</function></literal>
19244         </entry>
19245        <entry><type>bigint</type></entry>
19246        <entry>
19247         Total disk space used by indexes attached to the specified table
19248        </entry>
19249       </row>
19250       <row>
19251        <entry>
19252         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</function></literal>
19253         </entry>
19254        <entry><type>bigint</type></entry>
19255        <entry>
19256         Disk space used by the specified fork (<literal>'main'</literal>,
19257         <literal>'fsm'</literal>, <literal>'vm'</>, or <literal>'init'</>)
19258         of the specified table or index
19259        </entry>
19260       </row>
19261       <row>
19262        <entry>
19263         <literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
19264         </entry>
19265        <entry><type>bigint</type></entry>
19266        <entry>
19267         Shorthand for <literal>pg_relation_size(..., 'main')</literal>
19268        </entry>
19269       </row>
19270       <row>
19271        <entry>
19272         <literal><function>pg_size_bytes(<type>text</type>)</function></literal>
19273         </entry>
19274        <entry><type>bigint</type></entry>
19275        <entry>
19276          Converts a size in human-readable format with size units into bytes
19277        </entry>
19278       </row>
19279       <row>
19280        <entry>
19281         <literal><function>pg_size_pretty(<type>bigint</type>)</function></literal>
19282         </entry>
19283        <entry><type>text</type></entry>
19284        <entry>
19285          Converts a size in bytes expressed as a 64-bit integer into a
19286          human-readable format with size units
19287        </entry>
19288       </row>
19289       <row>
19290        <entry>
19291         <literal><function>pg_size_pretty(<type>numeric</type>)</function></literal>
19292         </entry>
19293        <entry><type>text</type></entry>
19294        <entry>
19295          Converts a size in bytes expressed as a numeric value into a
19296          human-readable format with size units
19297        </entry>
19298       </row>
19299       <row>
19300        <entry>
19301         <literal><function>pg_table_size(<type>regclass</type>)</function></literal>
19302         </entry>
19303        <entry><type>bigint</type></entry>
19304        <entry>
19305         Disk space used by the specified table, excluding indexes
19306         (but including TOAST, free space map, and visibility map)
19307        </entry>
19308       </row>
19309       <row>
19310        <entry>
19311         <literal><function>pg_tablespace_size(<type>oid</type>)</function></literal>
19312         </entry>
19313        <entry><type>bigint</type></entry>
19314        <entry>Disk space used by the tablespace with the specified OID</entry>
19315       </row>
19316       <row>
19317        <entry>
19318         <literal><function>pg_tablespace_size(<type>name</type>)</function></literal>
19319         </entry>
19320        <entry><type>bigint</type></entry>
19321        <entry>Disk space used by the tablespace with the specified name</entry>
19322       </row>
19323       <row>
19324        <entry>
19325         <literal><function>pg_total_relation_size(<type>regclass</type>)</function></literal>
19326         </entry>
19327        <entry><type>bigint</type></entry>
19328        <entry>
19329         Total disk space used by the specified table,
19330         including all indexes and <acronym>TOAST</> data
19331        </entry>
19332       </row>
19333      </tbody>
19334     </tgroup>
19335    </table>
19336
19337    <para>
19338     <function>pg_column_size</> shows the space used to store any individual
19339     data value.
19340    </para>
19341
19342    <para>
19343     <function>pg_total_relation_size</> accepts the OID or name of a
19344     table or toast table, and returns the total on-disk space used for
19345     that table, including all associated indexes.  This function is
19346     equivalent to <function>pg_table_size</function>
19347     <literal>+</> <function>pg_indexes_size</function>.
19348    </para>
19349
19350    <para>
19351     <function>pg_table_size</> accepts the OID or name of a table and
19352     returns the disk space needed for that table, exclusive of indexes.
19353     (TOAST space, free space map, and visibility map are included.)
19354    </para>
19355
19356    <para>
19357     <function>pg_indexes_size</> accepts the OID or name of a table and
19358     returns the total disk space used by all the indexes attached to that
19359     table.
19360    </para>
19361
19362    <para>
19363     <function>pg_database_size</function> and <function>pg_tablespace_size</>
19364     accept the OID or name of a database or tablespace, and return the total
19365     disk space used therein.  To use <function>pg_database_size</function>,
19366     you must have <literal>CONNECT</> permission on the specified database
19367     (which is granted by default).  To use <function>pg_tablespace_size</>,
19368     you must have <literal>CREATE</> permission on the specified tablespace,
19369     unless it is the default tablespace for the current database.
19370    </para>
19371
19372    <para>
19373     <function>pg_relation_size</> accepts the OID or name of a table, index
19374     or toast table, and returns the on-disk size in bytes of one fork of
19375     that relation.  (Note that for most purposes it is more convenient to
19376     use the higher-level functions <function>pg_total_relation_size</>
19377     or <function>pg_table_size</>, which sum the sizes of all forks.)
19378     With one argument, it returns the size of the main data fork of the
19379     relation.  The second argument can be provided to specify which fork
19380     to examine:
19381     <itemizedlist spacing="compact">
19382      <listitem>
19383       <para>
19384        <literal>'main'</literal> returns the size of the main
19385        data fork of the relation.
19386       </para>
19387      </listitem>
19388      <listitem>
19389       <para>
19390        <literal>'fsm'</literal> returns the size of the Free Space Map
19391        (see <xref linkend="storage-fsm">) associated with the relation.
19392       </para>
19393      </listitem>
19394      <listitem>
19395       <para>
19396        <literal>'vm'</literal> returns the size of the Visibility Map
19397        (see <xref linkend="storage-vm">) associated with the relation.
19398       </para>
19399      </listitem>
19400      <listitem>
19401       <para>
19402        <literal>'init'</literal> returns the size of the initialization
19403        fork, if any, associated with the relation.
19404       </para>
19405      </listitem>
19406     </itemizedlist>
19407    </para>
19408
19409    <para>
19410     <function>pg_size_pretty</> can be used to format the result of one of
19411     the other functions in a human-readable way, using bytes, kB, MB, GB or TB
19412     as appropriate.
19413    </para>
19414
19415    <para>
19416     <function>pg_size_bytes</> can be used to get the size in bytes from a
19417     string in human-readable format. The input may have units of bytes, kB,
19418     MB, GB or TB, and is parsed case-insensitively. If no units are specified,
19419     bytes are assumed.
19420    </para>
19421
19422    <note>
19423     <para>
19424      The units kB, MB, GB and TB used by the functions
19425      <function>pg_size_pretty</> and <function>pg_size_bytes</> are defined
19426      using powers of 2 rather than powers of 10, so 1kB is 1024 bytes, 1MB is
19427      1024<superscript>2</> = 1048576 bytes, and so on.
19428     </para>
19429    </note>
19430
19431    <para>
19432     The functions above that operate on tables or indexes accept a
19433     <type>regclass</> argument, which is simply the OID of the table or index
19434     in the <structname>pg_class</> system catalog.  You do not have to look up
19435     the OID by hand, however, since the <type>regclass</> data type's input
19436     converter will do the work for you.  Just write the table name enclosed in
19437     single quotes so that it looks like a literal constant.  For compatibility
19438     with the handling of ordinary <acronym>SQL</acronym> names, the string
19439     will be converted to lower case unless it contains double quotes around
19440     the table name.
19441    </para>
19442
19443    <para>
19444     If an OID that does not represent an existing object is passed as
19445     argument to one of the above functions, NULL is returned.
19446    </para>
19447
19448    <para>
19449     The functions shown in <xref linkend="functions-admin-dblocation"> assist
19450     in identifying the specific disk files associated with database objects.
19451    </para>
19452
19453    <indexterm>
19454     <primary>pg_relation_filenode</primary>
19455    </indexterm>
19456    <indexterm>
19457     <primary>pg_relation_filepath</primary>
19458    </indexterm>
19459    <indexterm>
19460     <primary>pg_filenode_relation</primary>
19461    </indexterm>
19462
19463    <table id="functions-admin-dblocation">
19464     <title>Database Object Location Functions</title>
19465     <tgroup cols="3">
19466      <thead>
19467       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
19468       </row>
19469      </thead>
19470
19471      <tbody>
19472       <row>
19473        <entry>
19474         <literal><function>pg_relation_filenode(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
19475         </entry>
19476        <entry><type>oid</type></entry>
19477        <entry>
19478         Filenode number of the specified relation
19479        </entry>
19480       </row>
19481       <row>
19482        <entry>
19483         <literal><function>pg_relation_filepath(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
19484         </entry>
19485        <entry><type>text</type></entry>
19486        <entry>
19487         File path name of the specified relation
19488        </entry>
19489       </row>
19490       <row>
19491        <entry>
19492         <literal><function>pg_filenode_relation(<parameter>tablespace</parameter> <type>oid</type>, <parameter>filenode</parameter> <type>oid</type>)</function></literal>
19493         </entry>
19494        <entry><type>regclass</type></entry>
19495        <entry>
19496         Find the relation associated with a given tablespace and filenode
19497        </entry>
19498       </row>
19499      </tbody>
19500     </tgroup>
19501    </table>
19502
19503    <para>
19504     <function>pg_relation_filenode</> accepts the OID or name of a table,
19505     index, sequence, or toast table, and returns the <quote>filenode</> number
19506     currently assigned to it.  The filenode is the base component of the file
19507     name(s) used for the relation (see <xref linkend="storage-file-layout">
19508     for more information).  For most tables the result is the same as
19509     <structname>pg_class</>.<structfield>relfilenode</>, but for certain
19510     system catalogs <structfield>relfilenode</> is zero and this function must
19511     be used to get the correct value.  The function returns NULL if passed
19512     a relation that does not have storage, such as a view.
19513    </para>
19514
19515    <para>
19516     <function>pg_relation_filepath</> is similar to
19517     <function>pg_relation_filenode</>, but it returns the entire file path name
19518     (relative to the database cluster's data directory <varname>PGDATA</>) of
19519     the relation.
19520    </para>
19521
19522    <para>
19523     <function>pg_filenode_relation</> is the reverse of
19524     <function>pg_relation_filenode</>. Given a <quote>tablespace</> OID and
19525     a <quote>filenode</>, it returns the associated relation's OID. For a table
19526     in the database's default tablespace, the tablespace can be specified as 0.
19527    </para>
19528
19529    <para>
19530     <xref linkend="functions-admin-collation"> lists functions used to manage
19531     collations.
19532    </para>
19533
19534    <table id="functions-admin-collation">
19535     <title>Collation Management Functions</title>
19536     <tgroup cols="3">
19537      <thead>
19538       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
19539      </thead>
19540
19541      <tbody>
19542       <row>
19543        <entry>
19544         <indexterm><primary>pg_import_system_collations</primary></indexterm>
19545         <literal><function>pg_import_system_collations(<parameter>if_not_exists</> <type>boolean</>, <parameter>schema</> <type>regnamespace</>)</function></literal>
19546        </entry>
19547        <entry><type>void</type></entry>
19548        <entry>Import operating system collations</entry>
19549       </row>
19550      </tbody>
19551     </tgroup>
19552    </table>
19553
19554    <para>
19555     <function>pg_import_system_collations</> populates the system
19556     catalog <literal>pg_collation</literal> with collations based on all the
19557     locales it finds on the operating system.  This is
19558     what <command>initdb</command> uses;
19559     see <xref linkend="collation-managing"> for more details.  If additional
19560     locales are installed into the operating system later on, this function
19561     can be run again to add collations for the new locales.  In that case, the
19562     parameter <parameter>if_not_exists</parameter> should be set to true to
19563     skip over existing collations.  The <parameter>schema</parameter>
19564     parameter would typically be <literal>pg_catalog</literal>, but that is
19565     not a requirement.  (Collation objects based on locales that are no longer
19566     present on the operating system are never removed by this function.)
19567    </para>
19568
19569   </sect2>
19570
19571   <sect2 id="functions-admin-index">
19572    <title>Index Maintenance Functions</title>
19573
19574    <indexterm>
19575     <primary>brin_summarize_new_values</primary>
19576    </indexterm>
19577
19578    <indexterm>
19579     <primary>gin_clean_pending_list</primary>
19580    </indexterm>
19581
19582    <para>
19583     <xref linkend="functions-admin-index-table"> shows the functions
19584     available for index maintenance tasks.
19585     These functions cannot be executed during recovery.
19586     Use of these functions is restricted to superusers and the owner
19587     of the given index.
19588    </para>
19589
19590    <table id="functions-admin-index-table">
19591     <title>Index Maintenance Functions</title>
19592     <tgroup cols="3">
19593      <thead>
19594       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
19595      </thead>
19596
19597      <tbody>
19598       <row>
19599        <entry>
19600         <literal><function>brin_summarize_new_values(<parameter>index</> <type>regclass</>)</function></literal>
19601        </entry>
19602        <entry><type>integer</type></entry>
19603        <entry>summarize page ranges not already summarized</entry>
19604       </row>
19605       <row>
19606        <entry>
19607         <literal><function>gin_clean_pending_list(<parameter>index</> <type>regclass</>)</function></literal>
19608        </entry>
19609        <entry><type>bigint</type></entry>
19610        <entry>move GIN pending list entries into main index structure</entry>
19611       </row>
19612      </tbody>
19613     </tgroup>
19614    </table>
19615
19616    <para>
19617     <function>brin_summarize_new_values</> accepts the OID or name of a
19618     BRIN index and inspects the index to find page ranges in the base table
19619     that are not currently summarized by the index; for any such range
19620     it creates a new summary index tuple by scanning the table pages.
19621     It returns the number of new page range summaries that were inserted
19622     into the index.
19623    </para>
19624
19625    <para>
19626     <function>gin_clean_pending_list</> accepts the OID or name of
19627     a GIN index and cleans up the pending list of the specified index
19628     by moving entries in it to the main GIN data structure in bulk.
19629     It returns the number of pages removed from the pending list.
19630     Note that if the argument is a GIN index built with
19631     the <literal>fastupdate</> option disabled, no cleanup happens and the
19632     return value is 0, because the index doesn't have a pending list.
19633     Please see <xref linkend="gin-fast-update"> and <xref linkend="gin-tips">
19634     for details of the pending list and <literal>fastupdate</> option.
19635    </para>
19636
19637   </sect2>
19638
19639   <sect2 id="functions-admin-genfile">
19640    <title>Generic File Access Functions</title>
19641
19642    <para>
19643     The functions shown in <xref
19644     linkend="functions-admin-genfile-table"> provide native access to
19645     files on the machine hosting the server. Only files within the
19646     database cluster directory and the <varname>log_directory</> can be
19647     accessed.  Use a relative path for files in the cluster directory,
19648     and a path matching the <varname>log_directory</> configuration setting
19649     for log files.  Use of these functions is restricted to superusers
19650     except where stated otherwise.
19651    </para>
19652
19653    <table id="functions-admin-genfile-table">
19654     <title>Generic File Access Functions</title>
19655     <tgroup cols="3">
19656      <thead>
19657       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
19658       </row>
19659      </thead>
19660
19661      <tbody>
19662       <row>
19663        <entry>
19664         <literal><function>pg_ls_dir(<parameter>dirname</> <type>text</> [, <parameter>missing_ok</> <type>boolean</>, <parameter>include_dot_dirs</> <type>boolean</>])</function></literal>
19665        </entry>
19666        <entry><type>setof text</type></entry>
19667        <entry>
19668         List the contents of a directory.
19669        </entry>
19670       </row>
19671       <row>
19672        <entry>
19673         <literal><function>pg_ls_logdir()</function></literal>
19674        </entry>
19675        <entry><type>setof record</type></entry>
19676        <entry>
19677         List the name, size, and last modification time of files in the log
19678         directory.  Access may be granted to non-superuser roles.
19679        </entry>
19680       </row>
19681       <row>
19682        <entry>
19683         <literal><function>pg_ls_waldir()</function></literal>
19684        </entry>
19685        <entry><type>setof record</type></entry>
19686        <entry>
19687         List the name, size, and last modification time of files in the WAL
19688         directory.  Access may be granted to non-superuser roles.
19689        </entry>
19690       </row>
19691       <row>
19692        <entry>
19693         <literal><function>pg_read_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</> [, <parameter>missing_ok</> <type>boolean</>] ])</function></literal>
19694        </entry>
19695        <entry><type>text</type></entry>
19696        <entry>
19697         Return the contents of a text file.
19698        </entry>
19699       </row>
19700       <row>
19701        <entry>
19702         <literal><function>pg_read_binary_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</> [, <parameter>missing_ok</> <type>boolean</>] ])</function></literal>
19703        </entry>
19704        <entry><type>bytea</type></entry>
19705        <entry>
19706         Return the contents of a file.
19707        </entry>
19708       </row>
19709       <row>
19710        <entry>
19711         <literal><function>pg_stat_file(<parameter>filename</> <type>text</>[, <parameter>missing_ok</> <type>boolean</type>])</function></literal>
19712        </entry>
19713        <entry><type>record</type></entry>
19714        <entry>
19715         Return information about a file.
19716        </entry>
19717       </row>
19718      </tbody>
19719     </tgroup>
19720    </table>
19721
19722    <para>
19723     Some of these functions take an optional <parameter>missing_ok</> parameter,
19724     which specifies the behavior when the file or directory does not exist.
19725     If <literal>true</literal>, the function returns NULL (except
19726     <function>pg_ls_dir</>, which returns an empty result set). If
19727     <literal>false</>, an error is raised. The default is <literal>false</>.
19728    </para>
19729
19730    <indexterm>
19731     <primary>pg_ls_dir</primary>
19732    </indexterm>
19733    <para>
19734     <function>pg_ls_dir</> returns the names of all files (and directories
19735     and other special files) in the specified directory. The <parameter>
19736     include_dot_dirs</> indicates whether <quote>.</> and <quote>..</> are
19737     included in the result set. The default is to exclude them
19738     (<literal>false</>), but including them can be useful when
19739     <parameter>missing_ok</> is <literal>true</literal>, to distinguish an
19740     empty directory from an non-existent directory.
19741    </para>
19742
19743    <indexterm>
19744     <primary>pg_ls_logdir</primary>
19745    </indexterm>
19746    <para>
19747     <function>pg_ls_logdir</> returns the name, size, and last modified time
19748     (mtime) of each file in the log directory. By default, only superusers
19749     can use this function, but access may be granted to others using
19750     <command>GRANT</command>.
19751    </para>
19752
19753    <indexterm>
19754     <primary>pg_ls_waldir</primary>
19755    </indexterm>
19756    <para>
19757     <function>pg_ls_waldir</> returns the name, size, and last modified time
19758     (mtime) of each file in the write ahead log (WAL) directory. By
19759     default only superusers can use this function, but access may be granted
19760     to others using <command>GRANT</command>.
19761    </para>
19762
19763    <indexterm>
19764     <primary>pg_read_file</primary>
19765    </indexterm>
19766    <para>
19767     <function>pg_read_file</> returns part of a text file, starting
19768     at the given <parameter>offset</>, returning at most <parameter>length</>
19769     bytes (less if the end of file is reached first).  If <parameter>offset</>
19770     is negative, it is relative to the end of the file.
19771     If <parameter>offset</> and <parameter>length</> are omitted, the entire
19772     file is returned.  The bytes read from the file are interpreted as a string
19773     in the server encoding; an error is thrown if they are not valid in that
19774     encoding.
19775    </para>
19776
19777    <indexterm>
19778     <primary>pg_read_binary_file</primary>
19779    </indexterm>
19780    <para>
19781     <function>pg_read_binary_file</> is similar to
19782     <function>pg_read_file</>, except that the result is a <type>bytea</type> value;
19783     accordingly, no encoding checks are performed.
19784     In combination with the <function>convert_from</> function, this function
19785     can be used to read a file in a specified encoding:
19786 <programlisting>
19787 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
19788 </programlisting>
19789    </para>
19790
19791    <indexterm>
19792     <primary>pg_stat_file</primary>
19793    </indexterm>
19794    <para>
19795     <function>pg_stat_file</> returns a record containing the file
19796     size, last accessed time stamp, last modified time stamp,
19797     last file status change time stamp (Unix platforms only),
19798     file creation time stamp (Windows only), and a <type>boolean</type>
19799     indicating if it is a directory.  Typical usages include:
19800 <programlisting>
19801 SELECT * FROM pg_stat_file('filename');
19802 SELECT (pg_stat_file('filename')).modification;
19803 </programlisting>
19804    </para>
19805
19806   </sect2>
19807
19808   <sect2 id="functions-advisory-locks">
19809    <title>Advisory Lock Functions</title>
19810
19811    <para>
19812     The functions shown in <xref linkend="functions-advisory-locks-table">
19813     manage advisory locks.  For details about proper use of these functions,
19814     see <xref linkend="advisory-locks">.
19815    </para>
19816
19817    <table id="functions-advisory-locks-table">
19818     <title>Advisory Lock Functions</title>
19819     <tgroup cols="3">
19820      <thead>
19821       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
19822       </row>
19823      </thead>
19824
19825      <tbody>
19826       <row>
19827        <entry>
19828         <literal><function>pg_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
19829        </entry>
19830        <entry><type>void</type></entry>
19831        <entry>Obtain exclusive session level advisory lock</entry>
19832       </row>
19833       <row>
19834        <entry>
19835         <literal><function>pg_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19836        </entry>
19837        <entry><type>void</type></entry>
19838        <entry>Obtain exclusive session level advisory lock</entry>
19839       </row>
19840       <row>
19841        <entry>
19842         <literal><function>pg_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
19843        </entry>
19844        <entry><type>void</type></entry>
19845        <entry>Obtain shared session level advisory lock</entry>
19846       </row>
19847       <row>
19848        <entry>
19849         <literal><function>pg_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19850        </entry>
19851        <entry><type>void</type></entry>
19852        <entry>Obtain shared session level advisory lock</entry>
19853       </row>
19854       <row>
19855        <entry>
19856         <literal><function>pg_advisory_unlock(<parameter>key</> <type>bigint</>)</function></literal>
19857        </entry>
19858        <entry><type>boolean</type></entry>
19859        <entry>Release an exclusive session level advisory lock</entry>
19860       </row>
19861       <row>
19862        <entry>
19863         <literal><function>pg_advisory_unlock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19864        </entry>
19865        <entry><type>boolean</type></entry>
19866        <entry>Release an exclusive session level advisory lock</entry>
19867       </row>
19868       <row>
19869        <entry>
19870         <literal><function>pg_advisory_unlock_all()</function></literal>
19871        </entry>
19872        <entry><type>void</type></entry>
19873        <entry>Release all session level advisory locks held by the current session</entry>
19874       </row>
19875       <row>
19876        <entry>
19877         <literal><function>pg_advisory_unlock_shared(<parameter>key</> <type>bigint</>)</function></literal>
19878        </entry>
19879        <entry><type>boolean</type></entry>
19880        <entry>Release a shared session level advisory lock</entry>
19881       </row>
19882       <row>
19883        <entry>
19884         <literal><function>pg_advisory_unlock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19885        </entry>
19886        <entry><type>boolean</type></entry>
19887        <entry>Release a shared session level advisory lock</entry>
19888       </row>
19889       <row>
19890        <entry>
19891         <literal><function>pg_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
19892        </entry>
19893        <entry><type>void</type></entry>
19894        <entry>Obtain exclusive transaction level advisory lock</entry>
19895       </row>
19896       <row>
19897        <entry>
19898         <literal><function>pg_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19899        </entry>
19900        <entry><type>void</type></entry>
19901        <entry>Obtain exclusive transaction level advisory lock</entry>
19902       </row>
19903       <row>
19904        <entry>
19905         <literal><function>pg_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
19906        </entry>
19907        <entry><type>void</type></entry>
19908        <entry>Obtain shared transaction level advisory lock</entry>
19909       </row>
19910       <row>
19911        <entry>
19912         <literal><function>pg_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19913        </entry>
19914        <entry><type>void</type></entry>
19915        <entry>Obtain shared transaction level advisory lock</entry>
19916       </row>
19917       <row>
19918        <entry>
19919         <literal><function>pg_try_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
19920        </entry>
19921        <entry><type>boolean</type></entry>
19922        <entry>Obtain exclusive session level advisory lock if available</entry>
19923       </row>
19924       <row>
19925        <entry>
19926         <literal><function>pg_try_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19927        </entry>
19928        <entry><type>boolean</type></entry>
19929        <entry>Obtain exclusive session level advisory lock if available</entry>
19930       </row>
19931       <row>
19932        <entry>
19933         <literal><function>pg_try_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
19934        </entry>
19935        <entry><type>boolean</type></entry>
19936        <entry>Obtain shared session level advisory lock if available</entry>
19937       </row>
19938       <row>
19939        <entry>
19940         <literal><function>pg_try_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19941        </entry>
19942        <entry><type>boolean</type></entry>
19943        <entry>Obtain shared session level advisory lock if available</entry>
19944       </row>
19945       <row>
19946        <entry>
19947         <literal><function>pg_try_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
19948        </entry>
19949        <entry><type>boolean</type></entry>
19950        <entry>Obtain exclusive transaction level advisory lock if available</entry>
19951       </row>
19952       <row>
19953        <entry>
19954         <literal><function>pg_try_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19955        </entry>
19956        <entry><type>boolean</type></entry>
19957        <entry>Obtain exclusive transaction level advisory lock if available</entry>
19958       </row>
19959       <row>
19960        <entry>
19961         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
19962        </entry>
19963        <entry><type>boolean</type></entry>
19964        <entry>Obtain shared transaction level advisory lock if available</entry>
19965       </row>
19966       <row>
19967        <entry>
19968         <literal><function>pg_try_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
19969        </entry>
19970        <entry><type>boolean</type></entry>
19971        <entry>Obtain shared transaction level advisory lock if available</entry>
19972       </row>
19973      </tbody>
19974     </tgroup>
19975    </table>
19976
19977    <indexterm>
19978     <primary>pg_advisory_lock</primary>
19979    </indexterm>
19980    <para>
19981     <function>pg_advisory_lock</> locks an application-defined resource,
19982     which can be identified either by a single 64-bit key value or two
19983     32-bit key values (note that these two key spaces do not overlap).
19984     If another session already holds a lock on the same resource identifier,
19985     this function will wait until the resource becomes available.  The lock
19986     is exclusive.  Multiple lock requests stack, so that if the same resource
19987     is locked three times it must then be unlocked three times to be
19988     released for other sessions' use.
19989    </para>
19990
19991    <indexterm>
19992     <primary>pg_advisory_lock_shared</primary>
19993    </indexterm>
19994    <para>
19995     <function>pg_advisory_lock_shared</> works the same as
19996     <function>pg_advisory_lock</>,
19997     except the lock can be shared with other sessions requesting shared locks.
19998     Only would-be exclusive lockers are locked out.
19999    </para>
20000
20001    <indexterm>
20002     <primary>pg_try_advisory_lock</primary>
20003    </indexterm>
20004    <para>
20005     <function>pg_try_advisory_lock</> is similar to
20006     <function>pg_advisory_lock</>, except the function will not wait for the
20007     lock to become available.  It will either obtain the lock immediately and
20008     return <literal>true</>, or return <literal>false</> if the lock cannot be
20009     acquired immediately.
20010    </para>
20011
20012    <indexterm>
20013     <primary>pg_try_advisory_lock_shared</primary>
20014    </indexterm>
20015    <para>
20016     <function>pg_try_advisory_lock_shared</> works the same as
20017     <function>pg_try_advisory_lock</>, except it attempts to acquire
20018     a shared rather than an exclusive lock.
20019    </para>
20020
20021    <indexterm>
20022     <primary>pg_advisory_unlock</primary>
20023    </indexterm>
20024    <para>
20025     <function>pg_advisory_unlock</> will release a previously-acquired
20026     exclusive session level advisory lock.  It
20027     returns <literal>true</> if the lock is successfully released.
20028     If the lock was not held, it will return <literal>false</>,
20029     and in addition, an SQL warning will be reported by the server.
20030    </para>
20031
20032    <indexterm>
20033     <primary>pg_advisory_unlock_shared</primary>
20034    </indexterm>
20035    <para>
20036     <function>pg_advisory_unlock_shared</> works the same as
20037     <function>pg_advisory_unlock</>,
20038     except it releases a shared session level advisory lock.
20039    </para>
20040
20041    <indexterm>
20042     <primary>pg_advisory_unlock_all</primary>
20043    </indexterm>
20044    <para>
20045     <function>pg_advisory_unlock_all</> will release all session level advisory
20046     locks held by the current session.  (This function is implicitly invoked
20047     at session end, even if the client disconnects ungracefully.)
20048    </para>
20049
20050    <indexterm>
20051     <primary>pg_advisory_xact_lock</primary>
20052    </indexterm>
20053    <para>
20054     <function>pg_advisory_xact_lock</> works the same as
20055     <function>pg_advisory_lock</>, except the lock is automatically released
20056     at the end of the current transaction and cannot be released explicitly.
20057    </para>
20058
20059    <indexterm>
20060     <primary>pg_advisory_xact_lock_shared</primary>
20061    </indexterm>
20062    <para>
20063     <function>pg_advisory_xact_lock_shared</> works the same as
20064     <function>pg_advisory_lock_shared</>, except the lock is automatically released
20065     at the end of the current transaction and cannot be released explicitly.
20066    </para>
20067
20068    <indexterm>
20069     <primary>pg_try_advisory_xact_lock</primary>
20070    </indexterm>
20071    <para>
20072     <function>pg_try_advisory_xact_lock</> works the same as
20073     <function>pg_try_advisory_lock</>, except the lock, if acquired,
20074     is automatically released at the end of the current transaction and
20075     cannot be released explicitly.
20076    </para>
20077
20078    <indexterm>
20079     <primary>pg_try_advisory_xact_lock_shared</primary>
20080    </indexterm>
20081    <para>
20082     <function>pg_try_advisory_xact_lock_shared</> works the same as
20083     <function>pg_try_advisory_lock_shared</>, except the lock, if acquired,
20084     is automatically released at the end of the current transaction and
20085     cannot be released explicitly.
20086    </para>
20087
20088   </sect2>
20089
20090   </sect1>
20091
20092   <sect1 id="functions-trigger">
20093    <title>Trigger Functions</title>
20094
20095    <indexterm>
20096      <primary>suppress_redundant_updates_trigger</primary>
20097    </indexterm>
20098
20099    <para>
20100       Currently <productname>PostgreSQL</> provides one built in trigger
20101       function, <function>suppress_redundant_updates_trigger</>,
20102       which will prevent any update
20103       that does not actually change the data in the row from taking place, in
20104       contrast to the normal behavior which always performs the update
20105       regardless of whether or not the data has changed. (This normal behavior
20106       makes updates run faster, since no checking is required, and is also
20107       useful in certain cases.)
20108     </para>
20109
20110     <para>
20111       Ideally, you should normally avoid running updates that don't actually
20112       change the data in the record. Redundant updates can cost considerable
20113       unnecessary time, especially if there are lots of indexes to alter,
20114       and space in dead rows that will eventually have to be vacuumed.
20115       However, detecting such situations in client code is not
20116       always easy, or even possible, and writing expressions to detect
20117       them can be error-prone. An alternative is to use
20118       <function>suppress_redundant_updates_trigger</>, which will skip
20119       updates that don't change the data. You should use this with care,
20120       however. The trigger takes a small but non-trivial time for each record,
20121       so if most of the records affected by an update are actually changed,
20122       use of this trigger will actually make the update run slower.
20123     </para>
20124
20125     <para>
20126       The <function>suppress_redundant_updates_trigger</> function can be
20127       added to a table like this:
20128 <programlisting>
20129 CREATE TRIGGER z_min_update
20130 BEFORE UPDATE ON tablename
20131 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
20132 </programlisting>
20133       In most cases, you would want to fire this trigger last for each row.
20134       Bearing in mind that triggers fire in name order, you would then
20135       choose a trigger name that comes after the name of any other trigger
20136       you might have on the table.
20137     </para>
20138     <para>
20139        For more information about creating triggers, see
20140         <xref linkend="SQL-CREATETRIGGER">.
20141     </para>
20142   </sect1>
20143
20144   <sect1 id="functions-event-triggers">
20145    <title>Event Trigger Functions</title>
20146
20147    <para>
20148     <productname>PostgreSQL</> provides these helper functions
20149     to retrieve information from event triggers.
20150    </para>
20151
20152    <para>
20153     For more information about event triggers,
20154     see <xref linkend="event-triggers">.
20155    </para>
20156
20157   <sect2 id="pg-event-trigger-ddl-command-end-functions">
20158    <title>Capturing Changes at Command End</title>
20159
20160    <indexterm>
20161     <primary>pg_event_trigger_ddl_commands</primary>
20162    </indexterm>
20163
20164    <para>
20165     <function>pg_event_trigger_ddl_commands</> returns a list of
20166     <acronym>DDL</acronym> commands executed by each user action,
20167     when invoked in a function attached to a
20168     <literal>ddl_command_end</> event trigger.  If called in any other
20169     context, an error is raised.
20170     <function>pg_event_trigger_ddl_commands</> returns one row for each
20171     base command executed; some commands that are a single SQL sentence
20172     may return more than one row.  This function returns the following
20173     columns:
20174
20175     <informaltable>
20176      <tgroup cols="3">
20177       <thead>
20178        <row>
20179         <entry>Name</entry>
20180         <entry>Type</entry>
20181         <entry>Description</entry>
20182        </row>
20183       </thead>
20184
20185       <tbody>
20186        <row>
20187         <entry><literal>classid</literal></entry>
20188         <entry><type>Oid</type></entry>
20189         <entry>OID of catalog the object belongs in</entry>
20190        </row>
20191        <row>
20192         <entry><literal>objid</literal></entry>
20193         <entry><type>Oid</type></entry>
20194         <entry>OID of the object in the catalog</entry>
20195        </row>
20196        <row>
20197         <entry><literal>objsubid</literal></entry>
20198         <entry><type>integer</type></entry>
20199         <entry>Object sub-id (e.g. attribute number for columns)</entry>
20200        </row>
20201        <row>
20202         <entry><literal>command_tag</literal></entry>
20203         <entry><type>text</type></entry>
20204         <entry>command tag</entry>
20205        </row>
20206        <row>
20207         <entry><literal>object_type</literal></entry>
20208         <entry><type>text</type></entry>
20209         <entry>Type of the object</entry>
20210        </row>
20211        <row>
20212         <entry><literal>schema_name</literal></entry>
20213         <entry><type>text</type></entry>
20214         <entry>
20215          Name of the schema the object belongs in, if any; otherwise <literal>NULL</>.
20216          No quoting is applied.
20217         </entry>
20218        </row>
20219        <row>
20220         <entry><literal>object_identity</literal></entry>
20221         <entry><type>text</type></entry>
20222         <entry>
20223          Text rendering of the object identity, schema-qualified. Each and every
20224          identifier present in the identity is quoted if necessary.
20225         </entry>
20226        </row>
20227        <row>
20228         <entry><literal>in_extension</literal></entry>
20229         <entry><type>bool</type></entry>
20230         <entry>whether the command is part of an extension script</entry>
20231        </row>
20232        <row>
20233         <entry><literal>command</literal></entry>
20234         <entry><type>pg_ddl_command</type></entry>
20235         <entry>
20236          A complete representation of the command, in internal format.
20237          This cannot be output directly, but it can be passed to other
20238          functions to obtain different pieces of information about the
20239          command.
20240         </entry>
20241        </row>
20242       </tbody>
20243      </tgroup>
20244     </informaltable>
20245    </para>
20246   </sect2>
20247
20248   <sect2 id="pg-event-trigger-sql-drop-functions">
20249    <title>Processing Objects Dropped by a DDL Command</title>
20250
20251    <indexterm>
20252      <primary>pg_event_trigger_dropped_objects</primary>
20253    </indexterm>
20254
20255    <para>
20256     <function>pg_event_trigger_dropped_objects</> returns a list of all objects
20257     dropped by the command in whose <literal>sql_drop</> event it is called.
20258     If called in any other context,
20259     <function>pg_event_trigger_dropped_objects</> raises an error.
20260     <function>pg_event_trigger_dropped_objects</> returns the following columns:
20261
20262     <informaltable>
20263      <tgroup cols="3">
20264       <thead>
20265        <row>
20266         <entry>Name</entry>
20267         <entry>Type</entry>
20268         <entry>Description</entry>
20269        </row>
20270       </thead>
20271
20272       <tbody>
20273        <row>
20274         <entry><literal>classid</literal></entry>
20275         <entry><type>Oid</type></entry>
20276         <entry>OID of catalog the object belonged in</entry>
20277        </row>
20278        <row>
20279         <entry><literal>objid</literal></entry>
20280         <entry><type>Oid</type></entry>
20281         <entry>OID the object had within the catalog</entry>
20282        </row>
20283        <row>
20284         <entry><literal>objsubid</literal></entry>
20285         <entry><type>int32</type></entry>
20286         <entry>Object sub-id (e.g. attribute number for columns)</entry>
20287        </row>
20288        <row>
20289         <entry><literal>original</literal></entry>
20290         <entry><type>bool</type></entry>
20291         <entry>Flag used to identify the root object(s) of the deletion</entry>
20292        </row>
20293        <row>
20294         <entry><literal>normal</literal></entry>
20295         <entry><type>bool</type></entry>
20296         <entry>
20297          Flag indicating that there's a normal dependency relationship
20298          in the dependency graph leading to this object
20299         </entry>
20300        </row>
20301        <row>
20302         <entry><literal>is_temporary</literal></entry>
20303         <entry><type>bool</type></entry>
20304         <entry>
20305          Flag indicating that the object was a temporary object.
20306         </entry>
20307        </row>
20308        <row>
20309         <entry><literal>object_type</literal></entry>
20310         <entry><type>text</type></entry>
20311         <entry>Type of the object</entry>
20312        </row>
20313        <row>
20314         <entry><literal>schema_name</literal></entry>
20315         <entry><type>text</type></entry>
20316         <entry>
20317          Name of the schema the object belonged in, if any; otherwise <literal>NULL</>.
20318          No quoting is applied.
20319         </entry>
20320        </row>
20321        <row>
20322         <entry><literal>object_name</literal></entry>
20323         <entry><type>text</type></entry>
20324         <entry>
20325          Name of the object, if the combination of schema and name can be
20326          used as a unique identifier for the object; otherwise <literal>NULL</>.
20327          No quoting is applied, and name is never schema-qualified.
20328         </entry>
20329        </row>
20330        <row>
20331         <entry><literal>object_identity</literal></entry>
20332         <entry><type>text</type></entry>
20333         <entry>
20334          Text rendering of the object identity, schema-qualified. Each and every
20335          identifier present in the identity is quoted if necessary.
20336         </entry>
20337        </row>
20338        <row>
20339         <entry><literal>address_names</literal></entry>
20340         <entry><type>text[]</type></entry>
20341         <entry>
20342          An array that, together with <literal>object_type</literal> and
20343          <literal>address_args</literal>,
20344          can be used by the <function>pg_get_object_address()</function> to
20345          recreate the object address in a remote server containing an
20346          identically named object of the same kind.
20347         </entry>
20348        </row>
20349        <row>
20350         <entry><literal>address_args</literal></entry>
20351         <entry><type>text[]</type></entry>
20352         <entry>
20353          Complement for <literal>address_names</literal> above.
20354         </entry>
20355        </row>
20356       </tbody>
20357      </tgroup>
20358     </informaltable>
20359    </para>
20360
20361    <para>
20362     The <function>pg_event_trigger_dropped_objects</> function can be used
20363     in an event trigger like this:
20364 <programlisting>
20365 CREATE FUNCTION test_event_trigger_for_drops()
20366         RETURNS event_trigger LANGUAGE plpgsql AS $$
20367 DECLARE
20368     obj record;
20369 BEGIN
20370     FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
20371     LOOP
20372         RAISE NOTICE '% dropped object: % %.% %',
20373                      tg_tag,
20374                      obj.object_type,
20375                      obj.schema_name,
20376                      obj.object_name,
20377                      obj.object_identity;
20378     END LOOP;
20379 END
20380 $$;
20381 CREATE EVENT TRIGGER test_event_trigger_for_drops
20382    ON sql_drop
20383    EXECUTE PROCEDURE test_event_trigger_for_drops();
20384 </programlisting>
20385     </para>
20386   </sect2>
20387
20388   <sect2 id="pg-event-trigger-table-rewrite-functions">
20389    <title>Handling a Table Rewrite Event</title>
20390
20391    <para>
20392     The functions shown in
20393     <xref linkend="functions-event-trigger-table-rewrite">
20394     provide information about a table for which a
20395     <literal>table_rewrite</> event has just been called.
20396     If called in any other context, an error is raised.
20397    </para>
20398
20399    <table id="functions-event-trigger-table-rewrite">
20400     <title>Table Rewrite information</title>
20401     <tgroup cols="3">
20402      <thead>
20403       <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
20404      </thead>
20405
20406      <tbody>
20407       <row>
20408        <entry>
20409         <indexterm><primary>pg_event_trigger_table_rewrite_oid</primary></indexterm>
20410         <literal><function>pg_event_trigger_table_rewrite_oid()</function></literal>
20411        </entry>
20412        <entry><type>Oid</type></entry>
20413        <entry>The OID of the table about to be rewritten.</entry>
20414       </row>
20415
20416       <row>
20417        <entry>
20418         <indexterm><primary>pg_event_trigger_table_rewrite_reason</primary></indexterm>
20419         <literal><function>pg_event_trigger_table_rewrite_reason()</function></literal>
20420        </entry>
20421        <entry><type>int</type></entry>
20422        <entry>
20423         The reason code(s) explaining the reason for rewriting. The exact
20424         meaning of the codes is release dependent.
20425        </entry>
20426       </row>
20427      </tbody>
20428     </tgroup>
20429    </table>
20430
20431    <para>
20432     The <function>pg_event_trigger_table_rewrite_oid</> function can be used
20433     in an event trigger like this:
20434 <programlisting>
20435 CREATE FUNCTION test_event_trigger_table_rewrite_oid()
20436  RETURNS event_trigger
20437  LANGUAGE plpgsql AS
20438 $$
20439 BEGIN
20440   RAISE NOTICE 'rewriting table % for reason %',
20441                 pg_event_trigger_table_rewrite_oid()::regclass,
20442                 pg_event_trigger_table_rewrite_reason();
20443 END;
20444 $$;
20445
20446 CREATE EVENT TRIGGER test_table_rewrite_oid
20447                   ON table_rewrite
20448    EXECUTE PROCEDURE test_event_trigger_table_rewrite_oid();
20449 </programlisting>
20450     </para>
20451   </sect2>
20452   </sect1>
20453
20454 </chapter>