Migrate the former contrib/txid module into core. This will make it easier
[PostgreSQL.git] / doc / src / sgml / func.sgml
blobbb95da121c24618d9012e7d6d6f5a69eb129270e
1 <!-- $PostgreSQL$ -->
3 <chapter id="functions">
4 <title>Functions and Operators</title>
6 <indexterm zone="functions">
7 <primary>function</primary>
8 </indexterm>
10 <indexterm zone="functions">
11 <primary>operator</primary>
12 </indexterm>
14 <para>
15 <productname>PostgreSQL</productname> provides a large number of
16 functions and operators for the built-in data types. Users can also
17 define their own functions and operators, as described in
18 <xref linkend="server-programming">. The
19 <application>psql</application> commands <command>\df</command> and
20 <command>\do</command> can be used to show the list of all actually
21 available functions and operators, respectively.
22 </para>
24 <para>
25 If you are concerned about portability then take note that most of
26 the functions and operators described in this chapter, with the
27 exception of the most trivial arithmetic and comparison operators
28 and some explicitly marked functions, are not specified by the
29 <acronym>SQL</acronym> standard. Some of the extended functionality
30 is present in other <acronym>SQL</acronym> database management
31 systems, and in many cases this functionality is compatible and
32 consistent between the various implementations. This chapter is also
33 not exhaustive; additional functions appear in relevant sections of
34 the manual.
35 </para>
38 <sect1 id="functions-logical">
39 <title>Logical Operators</title>
41 <indexterm zone="functions-logical">
42 <primary>operator</primary>
43 <secondary>logical</secondary>
44 </indexterm>
46 <indexterm>
47 <primary>Boolean</primary>
48 <secondary>operators</secondary>
49 <see>operators, logical</see>
50 </indexterm>
52 <para>
53 The usual logical operators are available:
55 <indexterm>
56 <primary>AND (operator)</primary>
57 </indexterm>
59 <indexterm>
60 <primary>OR (operator)</primary>
61 </indexterm>
63 <indexterm>
64 <primary>NOT (operator)</primary>
65 </indexterm>
67 <indexterm>
68 <primary>conjunction</primary>
69 </indexterm>
71 <indexterm>
72 <primary>disjunction</primary>
73 </indexterm>
75 <indexterm>
76 <primary>negation</primary>
77 </indexterm>
79 <simplelist>
80 <member><literal>AND</></member>
81 <member><literal>OR</></member>
82 <member><literal>NOT</></member>
83 </simplelist>
85 <acronym>SQL</acronym> uses a three-valued Boolean logic where the null value represents
86 <quote>unknown</quote>. Observe the following truth tables:
88 <informaltable>
89 <tgroup cols="4">
90 <thead>
91 <row>
92 <entry><replaceable>a</replaceable></entry>
93 <entry><replaceable>b</replaceable></entry>
94 <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
95 <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
96 </row>
97 </thead>
99 <tbody>
100 <row>
101 <entry>TRUE</entry>
102 <entry>TRUE</entry>
103 <entry>TRUE</entry>
104 <entry>TRUE</entry>
105 </row>
107 <row>
108 <entry>TRUE</entry>
109 <entry>FALSE</entry>
110 <entry>FALSE</entry>
111 <entry>TRUE</entry>
112 </row>
114 <row>
115 <entry>TRUE</entry>
116 <entry>NULL</entry>
117 <entry>NULL</entry>
118 <entry>TRUE</entry>
119 </row>
121 <row>
122 <entry>FALSE</entry>
123 <entry>FALSE</entry>
124 <entry>FALSE</entry>
125 <entry>FALSE</entry>
126 </row>
128 <row>
129 <entry>FALSE</entry>
130 <entry>NULL</entry>
131 <entry>FALSE</entry>
132 <entry>NULL</entry>
133 </row>
135 <row>
136 <entry>NULL</entry>
137 <entry>NULL</entry>
138 <entry>NULL</entry>
139 <entry>NULL</entry>
140 </row>
141 </tbody>
142 </tgroup>
143 </informaltable>
145 <informaltable>
146 <tgroup cols="2">
147 <thead>
148 <row>
149 <entry><replaceable>a</replaceable></entry>
150 <entry>NOT <replaceable>a</replaceable></entry>
151 </row>
152 </thead>
154 <tbody>
155 <row>
156 <entry>TRUE</entry>
157 <entry>FALSE</entry>
158 </row>
160 <row>
161 <entry>FALSE</entry>
162 <entry>TRUE</entry>
163 </row>
165 <row>
166 <entry>NULL</entry>
167 <entry>NULL</entry>
168 </row>
169 </tbody>
170 </tgroup>
171 </informaltable>
172 </para>
174 <para>
175 The operators <literal>AND</literal> and <literal>OR</literal> are
176 commutative, that is, you can switch the left and right operand
177 without affecting the result. But see <xref
178 linkend="syntax-express-eval"> for more information about the
179 order of evaluation of subexpressions.
180 </para>
181 </sect1>
183 <sect1 id="functions-comparison">
184 <title>Comparison Operators</title>
186 <indexterm zone="functions-comparison">
187 <primary>comparison</primary>
188 <secondary>operators</secondary>
189 </indexterm>
191 <para>
192 The usual comparison operators are available, shown in <xref
193 linkend="functions-comparison-table">.
194 </para>
196 <table id="functions-comparison-table">
197 <title>Comparison Operators</title>
198 <tgroup cols="2">
199 <thead>
200 <row>
201 <entry>Operator</entry>
202 <entry>Description</entry>
203 </row>
204 </thead>
206 <tbody>
207 <row>
208 <entry> <literal>&lt;</literal> </entry>
209 <entry>less than</entry>
210 </row>
212 <row>
213 <entry> <literal>&gt;</literal> </entry>
214 <entry>greater than</entry>
215 </row>
217 <row>
218 <entry> <literal>&lt;=</literal> </entry>
219 <entry>less than or equal to</entry>
220 </row>
222 <row>
223 <entry> <literal>&gt;=</literal> </entry>
224 <entry>greater than or equal to</entry>
225 </row>
227 <row>
228 <entry> <literal>=</literal> </entry>
229 <entry>equal</entry>
230 </row>
232 <row>
233 <entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
234 <entry>not equal</entry>
235 </row>
236 </tbody>
237 </tgroup>
238 </table>
240 <note>
241 <para>
242 The <literal>!=</literal> operator is converted to
243 <literal>&lt;&gt;</literal> in the parser stage. It is not
244 possible to implement <literal>!=</literal> and
245 <literal>&lt;&gt;</literal> operators that do different things.
246 </para>
247 </note>
249 <para>
250 Comparison operators are available for all data types where this
251 makes sense. All comparison operators are binary operators that
252 return values of type <type>boolean</type>; expressions like
253 <literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
254 no <literal>&lt;</literal> operator to compare a Boolean value with
255 <literal>3</literal>).
256 </para>
258 <para>
259 <indexterm>
260 <primary>BETWEEN</primary>
261 </indexterm>
262 In addition to the comparison operators, the special
263 <token>BETWEEN</token> construct is available.
264 <synopsis>
265 <replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
266 </synopsis>
267 is equivalent to
268 <synopsis>
269 <replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
270 </synopsis>
271 Similarly,
272 <synopsis>
273 <replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
274 </synopsis>
275 is equivalent to
276 <synopsis>
277 <replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
278 </synopsis>
279 There is no difference between the two respective forms apart from
280 the <acronym>CPU</acronym> cycles required to rewrite the first one
281 into the second one internally.
282 <indexterm>
283 <primary>BETWEEN SYMMETRIC</primary>
284 </indexterm>
285 <token>BETWEEN SYMMETRIC</> is the same as <literal>BETWEEN</>
286 except there is no requirement that the argument to the left of <literal>AND</> be less than
287 or equal to the argument on the right; the proper range is automatically determined.
288 </para>
290 <para>
291 <indexterm>
292 <primary>IS NULL</primary>
293 </indexterm>
294 <indexterm>
295 <primary>IS NOT NULL</primary>
296 </indexterm>
297 <indexterm>
298 <primary>ISNULL</primary>
299 </indexterm>
300 <indexterm>
301 <primary>NOTNULL</primary>
302 </indexterm>
303 To check whether a value is or is not null, use the constructs
304 <synopsis>
305 <replaceable>expression</replaceable> IS NULL
306 <replaceable>expression</replaceable> IS NOT NULL
307 </synopsis>
308 or the equivalent, but nonstandard, constructs
309 <synopsis>
310 <replaceable>expression</replaceable> ISNULL
311 <replaceable>expression</replaceable> NOTNULL
312 </synopsis>
313 <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
314 </para>
316 <para>
317 Do <emphasis>not</emphasis> write
318 <literal><replaceable>expression</replaceable> = NULL</literal>
319 because <literal>NULL</> is not <quote>equal to</quote>
320 <literal>NULL</>. (The null value represents an unknown value,
321 and it is not known whether two unknown values are equal.) This
322 behavior conforms to the SQL standard.
323 </para>
325 <tip>
326 <para>
327 Some applications might expect that
328 <literal><replaceable>expression</replaceable> = NULL</literal>
329 returns true if <replaceable>expression</replaceable> evaluates to
330 the null value. It is highly recommended that these applications
331 be modified to comply with the SQL standard. However, if that
332 cannot be done the <xref linkend="guc-transform-null-equals">
333 configuration variable is available. If it is enabled,
334 <productname>PostgreSQL</productname> will convert <literal>x =
335 NULL</literal> clauses to <literal>x IS NULL</literal>. This was
336 the default behavior in <productname>PostgreSQL</productname>
337 releases 6.5 through 7.1.
338 </para>
339 </tip>
341 <note>
342 <para>
343 If the <replaceable>expression</replaceable> is row-valued, then
344 <literal>IS NULL</> is true when the row expression itself is null
345 or when all the row's fields are null, while
346 <literal>IS NOT NULL</> is true when the row expression itself is non-null
347 and all the row's fields are non-null.
348 This definition conforms to the SQL standard, and is a change from the
349 inconsistent behavior exhibited by <productname>PostgreSQL</productname>
350 versions prior to 8.2.
351 </para>
352 </note>
354 <para>
355 <indexterm>
356 <primary>IS DISTINCT FROM</primary>
357 </indexterm>
358 <indexterm>
359 <primary>IS NOT DISTINCT FROM</primary>
360 </indexterm>
361 The ordinary comparison operators yield null (signifying <quote>unknown</>)
362 when either input is null. Another way to do comparisons is with the
363 <literal>IS <optional> NOT </> DISTINCT FROM</literal> construct:
364 <synopsis>
365 <replaceable>expression</replaceable> IS DISTINCT FROM <replaceable>expression</replaceable>
366 <replaceable>expression</replaceable> IS NOT DISTINCT FROM <replaceable>expression</replaceable>
367 </synopsis>
368 For non-null inputs, <literal>IS DISTINCT FROM</literal> is
369 the same as the <literal>&lt;&gt;</> operator. However, when both
370 inputs are null it will return false, and when just one input is
371 null it will return true. Similarly, <literal>IS NOT DISTINCT
372 FROM</literal> is identical to <literal>=</literal> for non-null
373 inputs, but it returns true when both inputs are null, and false when only
374 one input is null. Thus, these constructs effectively act as though null
375 were a normal data value, rather than <quote>unknown</>.
376 </para>
378 <para>
379 <indexterm>
380 <primary>IS TRUE</primary>
381 </indexterm>
382 <indexterm>
383 <primary>IS NOT TRUE</primary>
384 </indexterm>
385 <indexterm>
386 <primary>IS FALSE</primary>
387 </indexterm>
388 <indexterm>
389 <primary>IS NOT FALSE</primary>
390 </indexterm>
391 <indexterm>
392 <primary>IS UNKNOWN</primary>
393 </indexterm>
394 <indexterm>
395 <primary>IS NOT UNKNOWN</primary>
396 </indexterm>
397 Boolean values can also be tested using the constructs
398 <synopsis>
399 <replaceable>expression</replaceable> IS TRUE
400 <replaceable>expression</replaceable> IS NOT TRUE
401 <replaceable>expression</replaceable> IS FALSE
402 <replaceable>expression</replaceable> IS NOT FALSE
403 <replaceable>expression</replaceable> IS UNKNOWN
404 <replaceable>expression</replaceable> IS NOT UNKNOWN
405 </synopsis>
406 These will always return true or false, never a null value, even when the
407 operand is null.
408 A null input is treated as the logical value <quote>unknown</>.
409 Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
410 effectively the same as <literal>IS NULL</literal> and
411 <literal>IS NOT NULL</literal>, respectively, except that the input
412 expression must be of Boolean type.
413 </para>
415 <!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
416 <para>
417 <indexterm>
418 <primary>IS OF</primary>
419 </indexterm>
420 <indexterm>
421 <primary>IS NOT OF</primary>
422 </indexterm>
423 It is possible to check the data type of an expression using the
424 constructs
425 <synopsis>
426 <replaceable>expression</replaceable> IS OF (typename, ...)
427 <replaceable>expression</replaceable> IS NOT OF (typename, ...)
428 </synopsis>
429 They return a boolean value based on whether the expression's data
430 type is one of the listed data types.
431 </para>
434 </sect1>
436 <sect1 id="functions-math">
437 <title>Mathematical Functions and Operators</title>
439 <para>
440 Mathematical operators are provided for many
441 <productname>PostgreSQL</productname> types. For types without
442 common mathematical conventions for all possible permutations
443 (e.g., date/time types) we
444 describe the actual behavior in subsequent sections.
445 </para>
447 <para>
448 <xref linkend="functions-math-op-table"> shows the available mathematical operators.
449 </para>
451 <table id="functions-math-op-table">
452 <title>Mathematical Operators</title>
454 <tgroup cols="4">
455 <thead>
456 <row>
457 <entry>Operator</entry>
458 <entry>Description</entry>
459 <entry>Example</entry>
460 <entry>Result</entry>
461 </row>
462 </thead>
464 <tbody>
465 <row>
466 <entry> <literal>+</literal> </entry>
467 <entry>addition</entry>
468 <entry><literal>2 + 3</literal></entry>
469 <entry><literal>5</literal></entry>
470 </row>
472 <row>
473 <entry> <literal>-</literal> </entry>
474 <entry>subtraction</entry>
475 <entry><literal>2 - 3</literal></entry>
476 <entry><literal>-1</literal></entry>
477 </row>
479 <row>
480 <entry> <literal>*</literal> </entry>
481 <entry>multiplication</entry>
482 <entry><literal>2 * 3</literal></entry>
483 <entry><literal>6</literal></entry>
484 </row>
486 <row>
487 <entry> <literal>/</literal> </entry>
488 <entry>division (integer division truncates results)</entry>
489 <entry><literal>4 / 2</literal></entry>
490 <entry><literal>2</literal></entry>
491 </row>
493 <row>
494 <entry> <literal>%</literal> </entry>
495 <entry>modulo (remainder)</entry>
496 <entry><literal>5 % 4</literal></entry>
497 <entry><literal>1</literal></entry>
498 </row>
500 <row>
501 <entry> <literal>^</literal> </entry>
502 <entry>exponentiation</entry>
503 <entry><literal>2.0 ^ 3.0</literal></entry>
504 <entry><literal>8</literal></entry>
505 </row>
507 <row>
508 <entry> <literal>|/</literal> </entry>
509 <entry>square root</entry>
510 <entry><literal>|/ 25.0</literal></entry>
511 <entry><literal>5</literal></entry>
512 </row>
514 <row>
515 <entry> <literal>||/</literal> </entry>
516 <entry>cube root</entry>
517 <entry><literal>||/ 27.0</literal></entry>
518 <entry><literal>3</literal></entry>
519 </row>
521 <row>
522 <entry> <literal>!</literal> </entry>
523 <entry>factorial</entry>
524 <entry><literal>5 !</literal></entry>
525 <entry><literal>120</literal></entry>
526 </row>
528 <row>
529 <entry> <literal>!!</literal> </entry>
530 <entry>factorial (prefix operator)</entry>
531 <entry><literal>!! 5</literal></entry>
532 <entry><literal>120</literal></entry>
533 </row>
535 <row>
536 <entry> <literal>@</literal> </entry>
537 <entry>absolute value</entry>
538 <entry><literal>@ -5.0</literal></entry>
539 <entry><literal>5</literal></entry>
540 </row>
542 <row>
543 <entry> <literal>&amp;</literal> </entry>
544 <entry>bitwise AND</entry>
545 <entry><literal>91 &amp; 15</literal></entry>
546 <entry><literal>11</literal></entry>
547 </row>
549 <row>
550 <entry> <literal>|</literal> </entry>
551 <entry>bitwise OR</entry>
552 <entry><literal>32 | 3</literal></entry>
553 <entry><literal>35</literal></entry>
554 </row>
556 <row>
557 <entry> <literal>#</literal> </entry>
558 <entry>bitwise XOR</entry>
559 <entry><literal>17 # 5</literal></entry>
560 <entry><literal>20</literal></entry>
561 </row>
563 <row>
564 <entry> <literal>~</literal> </entry>
565 <entry>bitwise NOT</entry>
566 <entry><literal>~1</literal></entry>
567 <entry><literal>-2</literal></entry>
568 </row>
570 <row>
571 <entry> <literal>&lt;&lt;</literal> </entry>
572 <entry>bitwise shift left</entry>
573 <entry><literal>1 &lt;&lt; 4</literal></entry>
574 <entry><literal>16</literal></entry>
575 </row>
577 <row>
578 <entry> <literal>&gt;&gt;</literal> </entry>
579 <entry>bitwise shift right</entry>
580 <entry><literal>8 &gt;&gt; 2</literal></entry>
581 <entry><literal>2</literal></entry>
582 </row>
584 </tbody>
585 </tgroup>
586 </table>
588 <para>
589 The bitwise operators work only on integral data types, whereas
590 the others are available for all numeric data types. The bitwise
591 operators are also available for the bit
592 string types <type>bit</type> and <type>bit varying</type>, as
593 shown in <xref linkend="functions-bit-string-op-table">.
594 </para>
596 <para>
597 <xref linkend="functions-math-func-table"> shows the available
598 mathematical functions. In the table, <literal>dp</literal>
599 indicates <type>double precision</type>. Many of these functions
600 are provided in multiple forms with different argument types.
601 Except where noted, any given form of a function returns the same
602 data type as its argument.
603 The functions working with <type>double precision</type> data are mostly
604 implemented on top of the host system's C library; accuracy and behavior in
605 boundary cases can therefore vary depending on the host system.
606 </para>
608 <indexterm>
609 <primary>abs</primary>
610 </indexterm>
611 <indexterm>
612 <primary>cbrt</primary>
613 </indexterm>
614 <indexterm>
615 <primary>ceiling</primary>
616 </indexterm>
617 <indexterm>
618 <primary>degrees</primary>
619 </indexterm>
620 <indexterm>
621 <primary>exp</primary>
622 </indexterm>
623 <indexterm>
624 <primary>floor</primary>
625 </indexterm>
626 <indexterm>
627 <primary>ln</primary>
628 </indexterm>
629 <indexterm>
630 <primary>log</primary>
631 </indexterm>
632 <indexterm>
633 <primary>mod</primary>
634 </indexterm>
635 <indexterm>
636 <primary>pi</primary>
637 </indexterm>
638 <indexterm>
639 <primary>power</primary>
640 </indexterm>
641 <indexterm>
642 <primary>radians</primary>
643 </indexterm>
644 <indexterm>
645 <primary>random</primary>
646 </indexterm>
647 <indexterm>
648 <primary>round</primary>
649 </indexterm>
650 <indexterm>
651 <primary>setseed</primary>
652 </indexterm>
653 <indexterm>
654 <primary>sign</primary>
655 </indexterm>
656 <indexterm>
657 <primary>sqrt</primary>
658 </indexterm>
659 <indexterm>
660 <primary>trunc</primary>
661 </indexterm>
662 <indexterm>
663 <primary>width_bucket</primary>
664 </indexterm>
666 <table id="functions-math-func-table">
667 <title>Mathematical Functions</title>
668 <tgroup cols="5">
669 <thead>
670 <row>
671 <entry>Function</entry>
672 <entry>Return Type</entry>
673 <entry>Description</entry>
674 <entry>Example</entry>
675 <entry>Result</entry>
676 </row>
677 </thead>
679 <tbody>
680 <row>
681 <entry><literal><function>abs</>(<replaceable>x</replaceable>)</literal></entry>
682 <entry>(same as <replaceable>x</>)</entry>
683 <entry>absolute value</entry>
684 <entry><literal>abs(-17.4)</literal></entry>
685 <entry><literal>17.4</literal></entry>
686 </row>
688 <row>
689 <entry><literal><function>cbrt</function>(<type>dp</type>)</literal></entry>
690 <entry><type>dp</type></entry>
691 <entry>cube root</entry>
692 <entry><literal>cbrt(27.0)</literal></entry>
693 <entry><literal>3</literal></entry>
694 </row>
696 <row>
697 <entry><literal><function>ceil</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
698 <entry>(same as input)</entry>
699 <entry>smallest integer not less than argument</entry>
700 <entry><literal>ceil(-42.8)</literal></entry>
701 <entry><literal>-42</literal></entry>
702 </row>
704 <row>
705 <entry><literal><function>ceiling</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
706 <entry>(same as input)</entry>
707 <entry>smallest integer not less than argument (alias for <function>ceil</function>)</entry>
708 <entry><literal>ceiling(-95.3)</literal></entry>
709 <entry><literal>-95</literal></entry>
710 </row>
712 <row>
713 <entry><literal><function>degrees</function>(<type>dp</type>)</literal></entry>
714 <entry><type>dp</type></entry>
715 <entry>radians to degrees</entry>
716 <entry><literal>degrees(0.5)</literal></entry>
717 <entry><literal>28.6478897565412</literal></entry>
718 </row>
720 <row>
721 <entry><literal><function>exp</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
722 <entry>(same as input)</entry>
723 <entry>exponential</entry>
724 <entry><literal>exp(1.0)</literal></entry>
725 <entry><literal>2.71828182845905</literal></entry>
726 </row>
728 <row>
729 <entry><literal><function>floor</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
730 <entry>(same as input)</entry>
731 <entry>largest integer not greater than argument</entry>
732 <entry><literal>floor(-42.8)</literal></entry>
733 <entry><literal>-43</literal></entry>
734 </row>
736 <row>
737 <entry><literal><function>ln</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
738 <entry>(same as input)</entry>
739 <entry>natural logarithm</entry>
740 <entry><literal>ln(2.0)</literal></entry>
741 <entry><literal>0.693147180559945</literal></entry>
742 </row>
744 <row>
745 <entry><literal><function>log</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
746 <entry>(same as input)</entry>
747 <entry>base 10 logarithm</entry>
748 <entry><literal>log(100.0)</literal></entry>
749 <entry><literal>2</literal></entry>
750 </row>
752 <row>
753 <entry><literal><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
754 <parameter>x</parameter> <type>numeric</type>)</literal></entry>
755 <entry><type>numeric</type></entry>
756 <entry>logarithm to base <parameter>b</parameter></entry>
757 <entry><literal>log(2.0, 64.0)</literal></entry>
758 <entry><literal>6.0000000000</literal></entry>
759 </row>
761 <row>
762 <entry><literal><function>mod</function>(<parameter>y</parameter>,
763 <parameter>x</parameter>)</literal></entry>
764 <entry>(same as argument types)</entry>
765 <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
766 <entry><literal>mod(9,4)</literal></entry>
767 <entry><literal>1</literal></entry>
768 </row>
770 <row>
771 <entry><literal><function>pi</function>()</literal></entry>
772 <entry><type>dp</type></entry>
773 <entry><quote>&pi;</quote> constant</entry>
774 <entry><literal>pi()</literal></entry>
775 <entry><literal>3.14159265358979</literal></entry>
776 </row>
778 <row>
779 <entry><literal><function>power</function>(<parameter>a</parameter> <type>dp</type>,
780 <parameter>b</parameter> <type>dp</type>)</literal></entry>
781 <entry><type>dp</type></entry>
782 <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
783 <entry><literal>power(9.0, 3.0)</literal></entry>
784 <entry><literal>729</literal></entry>
785 </row>
787 <row>
788 <entry><literal><function>power</function>(<parameter>a</parameter> <type>numeric</type>,
789 <parameter>b</parameter> <type>numeric</type>)</literal></entry>
790 <entry><type>numeric</type></entry>
791 <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
792 <entry><literal>power(9.0, 3.0)</literal></entry>
793 <entry><literal>729</literal></entry>
794 </row>
796 <row>
797 <entry><literal><function>radians</function>(<type>dp</type>)</literal></entry>
798 <entry><type>dp</type></entry>
799 <entry>degrees to radians</entry>
800 <entry><literal>radians(45.0)</literal></entry>
801 <entry><literal>0.785398163397448</literal></entry>
802 </row>
804 <row>
805 <entry><literal><function>random</function>()</literal></entry>
806 <entry><type>dp</type></entry>
807 <entry>random value between 0.0 and 1.0</entry>
808 <entry><literal>random()</literal></entry>
809 <entry></entry>
810 </row>
812 <row>
813 <entry><literal><function>round</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
814 <entry>(same as input)</entry>
815 <entry>round to nearest integer</entry>
816 <entry><literal>round(42.4)</literal></entry>
817 <entry><literal>42</literal></entry>
818 </row>
820 <row>
821 <entry><literal><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
822 <entry><type>numeric</type></entry>
823 <entry>round to <parameter>s</parameter> decimal places</entry>
824 <entry><literal>round(42.4382, 2)</literal></entry>
825 <entry><literal>42.44</literal></entry>
826 </row>
828 <row>
829 <entry><literal><function>setseed</function>(<type>dp</type>)</literal></entry>
830 <entry><type>void</type></entry>
831 <entry>set seed for subsequent <literal>random()</literal> calls (value between 0 and 1.0)</entry>
832 <entry><literal>setseed(0.54823)</literal></entry>
833 <entry></entry>
834 </row>
836 <row>
837 <entry><literal><function>sign</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
838 <entry>(same as input)</entry>
839 <entry>sign of the argument (-1, 0, +1)</entry>
840 <entry><literal>sign(-8.4)</literal></entry>
841 <entry><literal>-1</literal></entry>
842 </row>
844 <row>
845 <entry><literal><function>sqrt</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
846 <entry>(same as input)</entry>
847 <entry>square root</entry>
848 <entry><literal>sqrt(2.0)</literal></entry>
849 <entry><literal>1.4142135623731</literal></entry>
850 </row>
852 <row>
853 <entry><literal><function>trunc</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
854 <entry>(same as input)</entry>
855 <entry>truncate toward zero</entry>
856 <entry><literal>trunc(42.8)</literal></entry>
857 <entry><literal>42</literal></entry>
858 </row>
860 <row>
861 <entry><literal><function>trunc</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</literal></entry>
862 <entry><type>numeric</type></entry>
863 <entry>truncate to <parameter>s</parameter> decimal places</entry>
864 <entry><literal>trunc(42.4382, 2)</literal></entry>
865 <entry><literal>42.43</literal></entry>
866 </row>
868 <row>
869 <entry><literal><function>width_bucket</function>(<parameter>op</parameter> <type>numeric</type>, <parameter>b1</parameter> <type>numeric</type>, <parameter>b2</parameter> <type>numeric</type>, <parameter>count</parameter> <type>int</type>)</literal></entry>
870 <entry><type>int</type></entry>
871 <entry>return the bucket to which <parameter>operand</> would
872 be assigned in an equidepth histogram with <parameter>count</>
873 buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
874 <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
875 <entry><literal>3</literal></entry>
876 </row>
878 <row>
879 <entry><literal><function>width_bucket</function>(<parameter>op</parameter> <type>dp</type>, <parameter>b1</parameter> <type>dp</type>, <parameter>b2</parameter> <type>dp</type>, <parameter>count</parameter> <type>int</type>)</literal></entry>
880 <entry><type>int</type></entry>
881 <entry>return the bucket to which <parameter>operand</> would
882 be assigned in an equidepth histogram with <parameter>count</>
883 buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
884 <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
885 <entry><literal>3</literal></entry>
886 </row>
887 </tbody>
888 </tgroup>
889 </table>
891 <para>
892 Finally, <xref linkend="functions-math-trig-table"> shows the
893 available trigonometric functions. All trigonometric functions
894 take arguments and return values of type <type>double
895 precision</type>.
896 </para>
898 <indexterm>
899 <primary>acos</primary>
900 </indexterm>
901 <indexterm>
902 <primary>asin</primary>
903 </indexterm>
904 <indexterm>
905 <primary>atan</primary>
906 </indexterm>
907 <indexterm>
908 <primary>atan2</primary>
909 </indexterm>
910 <indexterm>
911 <primary>cos</primary>
912 </indexterm>
913 <indexterm>
914 <primary>cot</primary>
915 </indexterm>
916 <indexterm>
917 <primary>sin</primary>
918 </indexterm>
919 <indexterm>
920 <primary>tan</primary>
921 </indexterm>
923 <table id="functions-math-trig-table">
924 <title>Trigonometric Functions</title>
926 <tgroup cols="2">
927 <thead>
928 <row>
929 <entry>Function</entry>
930 <entry>Description</entry>
931 </row>
932 </thead>
934 <tbody>
935 <row>
936 <entry><literal><function>acos</function>(<replaceable>x</replaceable>)</literal></entry>
937 <entry>inverse cosine</entry>
938 </row>
940 <row>
941 <entry><literal><function>asin</function>(<replaceable>x</replaceable>)</literal></entry>
942 <entry>inverse sine</entry>
943 </row>
945 <row>
946 <entry><literal><function>atan</function>(<replaceable>x</replaceable>)</literal></entry>
947 <entry>inverse tangent</entry>
948 </row>
950 <row>
951 <entry><literal><function>atan2</function>(<replaceable>y</replaceable>,
952 <replaceable>x</replaceable>)</literal></entry>
953 <entry>inverse tangent of
954 <literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
955 </row>
957 <row>
958 <entry><literal><function>cos</function>(<replaceable>x</replaceable>)</literal></entry>
959 <entry>cosine</entry>
960 </row>
962 <row>
963 <entry><literal><function>cot</function>(<replaceable>x</replaceable>)</literal></entry>
964 <entry>cotangent</entry>
965 </row>
967 <row>
968 <entry><literal><function>sin</function>(<replaceable>x</replaceable>)</literal></entry>
969 <entry>sine</entry>
970 </row>
972 <row>
973 <entry><literal><function>tan</function>(<replaceable>x</replaceable>)</literal></entry>
974 <entry>tangent</entry>
975 </row>
976 </tbody>
977 </tgroup>
978 </table>
980 </sect1>
983 <sect1 id="functions-string">
984 <title>String Functions and Operators</title>
986 <para>
987 This section describes functions and operators for examining and
988 manipulating string values. Strings in this context include values
989 of the types <type>character</type>, <type>character varying</type>,
990 and <type>text</type>. Unless otherwise noted, all
991 of the functions listed below work on all of these types, but be
992 wary of potential effects of automatic space-padding when using the
993 <type>character</type> type. Some functions also exist
994 natively for the bit-string types.
995 </para>
997 <para>
998 <acronym>SQL</acronym> defines some string functions with a special syntax
999 wherein certain key words rather than commas are used to separate the
1000 arguments. Details are in <xref linkend="functions-string-sql">.
1001 These functions are also implemented using the regular syntax for
1002 function invocation. (See <xref linkend="functions-string-other">.)
1003 </para>
1005 <note>
1006 <para>
1007 Before <productname>PostgreSQL</productname> 8.3, these functions would
1008 silently accept values of several non-string data types as well, due to
1009 the presence of implicit coercions from those data types to
1010 <type>text</>. Those coercions have been removed because they frequently
1011 caused surprising behaviors. However, the string concatenation operator
1012 (<literal>||</>) still accepts non-string input, so long as at least one
1013 input is of a string type, as shown in <xref
1014 linkend="functions-string-sql">. For other cases, insert an explicit
1015 coercion to <type>text</> if you need to duplicate the previous behavior.
1016 </para>
1017 </note>
1019 <indexterm>
1020 <primary>bit_length</primary>
1021 </indexterm>
1022 <indexterm>
1023 <primary>char_length</primary>
1024 </indexterm>
1025 <indexterm>
1026 <primary>lower</primary>
1027 </indexterm>
1028 <indexterm>
1029 <primary>octet_length</primary>
1030 </indexterm>
1031 <indexterm>
1032 <primary>overlay</primary>
1033 </indexterm>
1034 <indexterm>
1035 <primary>position</primary>
1036 </indexterm>
1037 <indexterm>
1038 <primary>substring</primary>
1039 </indexterm>
1040 <indexterm>
1041 <primary>trim</primary>
1042 </indexterm>
1043 <indexterm>
1044 <primary>upper</primary>
1045 </indexterm>
1047 <table id="functions-string-sql">
1048 <title><acronym>SQL</acronym> String Functions and Operators</title>
1049 <tgroup cols="5">
1050 <thead>
1051 <row>
1052 <entry>Function</entry>
1053 <entry>Return Type</entry>
1054 <entry>Description</entry>
1055 <entry>Example</entry>
1056 <entry>Result</entry>
1057 </row>
1058 </thead>
1060 <tbody>
1061 <row>
1062 <entry><literal><parameter>string</parameter> <literal>||</literal>
1063 <parameter>string</parameter></literal></entry>
1064 <entry> <type>text</type> </entry>
1065 <entry>
1066 String concatenation
1067 <indexterm>
1068 <primary>character string</primary>
1069 <secondary>concatenation</secondary>
1070 </indexterm>
1071 </entry>
1072 <entry><literal>'Post' || 'greSQL'</literal></entry>
1073 <entry><literal>PostgreSQL</literal></entry>
1074 </row>
1076 <row>
1077 <entry>
1078 <literal><parameter>string</parameter> <literal>||</literal>
1079 <parameter>non-string</parameter></literal>
1081 <literal><parameter>non-string</parameter> <literal>||</literal>
1082 <parameter>string</parameter></literal>
1083 </entry>
1084 <entry> <type>text</type> </entry>
1085 <entry>
1086 String concatenation with one non-string input
1087 </entry>
1088 <entry><literal>'Value: ' || 42</literal></entry>
1089 <entry><literal>Value: 42</literal></entry>
1090 </row>
1092 <row>
1093 <entry><literal><function>bit_length</function>(<parameter>string</parameter>)</literal></entry>
1094 <entry><type>int</type></entry>
1095 <entry>Number of bits in string</entry>
1096 <entry><literal>bit_length('jose')</literal></entry>
1097 <entry><literal>32</literal></entry>
1098 </row>
1100 <row>
1101 <entry><literal><function>char_length</function>(<parameter>string</parameter>)</literal> or <literal><function>character_length</function>(<parameter>string</parameter>)</literal></entry>
1102 <entry><type>int</type></entry>
1103 <entry>
1104 Number of characters in string
1105 <indexterm>
1106 <primary>character string</primary>
1107 <secondary>length</secondary>
1108 </indexterm>
1109 <indexterm>
1110 <primary>length</primary>
1111 <secondary sortas="character string">of a character string</secondary>
1112 <see>character string, length</see>
1113 </indexterm>
1114 </entry>
1115 <entry><literal>char_length('jose')</literal></entry>
1116 <entry><literal>4</literal></entry>
1117 </row>
1119 <row>
1120 <entry><literal><function>lower</function>(<parameter>string</parameter>)</literal></entry>
1121 <entry><type>text</type></entry>
1122 <entry>Convert string to lower case</entry>
1123 <entry><literal>lower('TOM')</literal></entry>
1124 <entry><literal>tom</literal></entry>
1125 </row>
1127 <row>
1128 <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
1129 <entry><type>int</type></entry>
1130 <entry>Number of bytes in string</entry>
1131 <entry><literal>octet_length('jose')</literal></entry>
1132 <entry><literal>4</literal></entry>
1133 </row>
1135 <row>
1136 <entry><literal><function>overlay</function>(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</literal></entry>
1137 <entry><type>text</type></entry>
1138 <entry>
1139 Replace substring
1140 </entry>
1141 <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
1142 <entry><literal>Thomas</literal></entry>
1143 </row>
1145 <row>
1146 <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
1147 <entry><type>int</type></entry>
1148 <entry>Location of specified substring</entry>
1149 <entry><literal>position('om' in 'Thomas')</literal></entry>
1150 <entry><literal>3</literal></entry>
1151 </row>
1153 <row>
1154 <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
1155 <entry><type>text</type></entry>
1156 <entry>
1157 Extract substring
1158 </entry>
1159 <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
1160 <entry><literal>hom</literal></entry>
1161 </row>
1163 <row>
1164 <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</literal></entry>
1165 <entry><type>text</type></entry>
1166 <entry>
1167 Extract substring matching POSIX regular expression. See
1168 <xref linkend="functions-matching"> for more information on pattern
1169 matching.
1170 </entry>
1171 <entry><literal>substring('Thomas' from '...$')</literal></entry>
1172 <entry><literal>mas</literal></entry>
1173 </row>
1175 <row>
1176 <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</literal></entry>
1177 <entry><type>text</type></entry>
1178 <entry>
1179 Extract substring matching <acronym>SQL</acronym> regular expression.
1180 See <xref linkend="functions-matching"> for more information on
1181 pattern matching.
1182 </entry>
1183 <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
1184 <entry><literal>oma</literal></entry>
1185 </row>
1187 <row>
1188 <entry>
1189 <literal><function>trim</function>(<optional>leading | trailing | both</optional>
1190 <optional><parameter>characters</parameter></optional> from
1191 <parameter>string</parameter>)</literal>
1192 </entry>
1193 <entry><type>text</type></entry>
1194 <entry>
1195 Remove the longest string containing only the
1196 <parameter>characters</parameter> (a space by default) from the
1197 start/end/both ends of the <parameter>string</parameter>
1198 </entry>
1199 <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
1200 <entry><literal>Tom</literal></entry>
1201 </row>
1203 <row>
1204 <entry><literal><function>upper</function>(<parameter>string</parameter>)</literal></entry>
1205 <entry><type>text</type></entry>
1206 <entry>Convert string to uppercase</entry>
1207 <entry><literal>upper('tom')</literal></entry>
1208 <entry><literal>TOM</literal></entry>
1209 </row>
1210 </tbody>
1211 </tgroup>
1212 </table>
1214 <para>
1215 Additional string manipulation functions are available and are
1216 listed in <xref linkend="functions-string-other">. Some of them are used internally to implement the
1217 <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
1218 </para>
1220 <indexterm>
1221 <primary>ascii</primary>
1222 </indexterm>
1223 <indexterm>
1224 <primary>btrim</primary>
1225 </indexterm>
1226 <indexterm>
1227 <primary>chr</primary>
1228 </indexterm>
1229 <indexterm>
1230 <primary>convert</primary>
1231 </indexterm>
1232 <indexterm>
1233 <primary>convert_from</primary>
1234 </indexterm>
1235 <indexterm>
1236 <primary>convert_to</primary>
1237 </indexterm>
1238 <indexterm>
1239 <primary>decode</primary>
1240 </indexterm>
1241 <indexterm>
1242 <primary>encode</primary>
1243 </indexterm>
1244 <indexterm>
1245 <primary>initcap</primary>
1246 </indexterm>
1247 <indexterm>
1248 <primary>lpad</primary>
1249 </indexterm>
1250 <indexterm>
1251 <primary>ltrim</primary>
1252 </indexterm>
1253 <indexterm>
1254 <primary>md5</primary>
1255 </indexterm>
1256 <indexterm>
1257 <primary>pg_client_encoding</primary>
1258 </indexterm>
1259 <indexterm>
1260 <primary>quote_ident</primary>
1261 </indexterm>
1262 <indexterm>
1263 <primary>quote_literal</primary>
1264 </indexterm>
1265 <indexterm>
1266 <primary>repeat</primary>
1267 </indexterm>
1268 <indexterm>
1269 <primary>replace</primary>
1270 </indexterm>
1271 <indexterm>
1272 <primary>rpad</primary>
1273 </indexterm>
1274 <indexterm>
1275 <primary>rtrim</primary>
1276 </indexterm>
1277 <indexterm>
1278 <primary>split_part</primary>
1279 </indexterm>
1280 <indexterm>
1281 <primary>strpos</primary>
1282 </indexterm>
1283 <indexterm>
1284 <primary>substr</primary>
1285 </indexterm>
1286 <indexterm>
1287 <primary>to_ascii</primary>
1288 </indexterm>
1289 <indexterm>
1290 <primary>to_hex</primary>
1291 </indexterm>
1292 <indexterm>
1293 <primary>translate</primary>
1294 </indexterm>
1296 <table id="functions-string-other">
1297 <title>Other String Functions</title>
1298 <tgroup cols="5">
1299 <thead>
1300 <row>
1301 <entry>Function</entry>
1302 <entry>Return Type</entry>
1303 <entry>Description</entry>
1304 <entry>Example</entry>
1305 <entry>Result</entry>
1306 </row>
1307 </thead>
1309 <tbody>
1310 <row>
1311 <entry><literal><function>ascii</function>(<parameter>string</parameter>)</literal></entry>
1312 <entry><type>int</type></entry>
1313 <entry>
1314 <acronym>ASCII</acronym> code of the first character of the
1315 argument. For <acronym>UTF8</acronym> returns the Unicode code
1316 point of the character. For other multi-byte encodings. the
1317 argument must be a strictly <acronym>ASCII</acronym> character.
1318 </entry>
1319 <entry><literal>ascii('x')</literal></entry>
1320 <entry><literal>120</literal></entry>
1321 </row>
1323 <row>
1324 <entry><literal><function>btrim</function>(<parameter>string</parameter> <type>text</type>
1325 <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal></entry>
1326 <entry><type>text</type></entry>
1327 <entry>
1328 Remove the longest string consisting only of characters
1329 in <parameter>characters</parameter> (a space by default)
1330 from the start and end of <parameter>string</parameter>
1331 </entry>
1332 <entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
1333 <entry><literal>trim</literal></entry>
1334 </row>
1336 <row>
1337 <entry><literal><function>chr</function>(<type>int</type>)</literal></entry>
1338 <entry><type>text</type></entry>
1339 <entry>
1340 Character with the given code. For <acronym>UTF8</acronym> the
1341 argument is treated as a Unicode code point. For other multi-byte
1342 encodings the argument must designate a strictly
1343 <acronym>ASCII</acronym> character.
1344 </entry>
1345 <entry><literal>chr(65)</literal></entry>
1346 <entry><literal>A</literal></entry>
1347 </row>
1349 <row>
1350 <entry>
1351 <literal><function>convert</function>(<parameter>string</parameter> <type>bytea</type>,
1352 <parameter>src_encoding</parameter> <type>name</type>,
1353 <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1354 </entry>
1355 <entry><type>bytea</type></entry>
1356 <entry>
1357 Convert string to <parameter>dest_encoding</parameter>. The
1358 original encoding is specified by
1359 <parameter>src_encoding</parameter>. The
1360 <parameter>string</parameter> must be valid in this encoding.
1361 Conversions can be defined by <command>CREATE CONVERSION</command>.
1362 Also there are some pre-defined conversions. See <xref
1363 linkend="conversion-names"> for available conversions.
1364 </entry>
1365 <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
1366 <entry><literal>text_in_utf8</literal> represented in ISO 8859-1 encoding</entry>
1367 </row>
1369 <row>
1370 <entry>
1371 <literal><function>convert_from</function>(<parameter>string</parameter> <type>bytea</type>,
1372 <parameter>src_encoding</parameter> <type>name</type>)</literal>
1373 </entry>
1374 <entry><type>text</type></entry>
1375 <entry>
1376 Convert string to the database encoding. The original encoding
1377 is specified by <parameter>src_encoding</parameter>. The
1378 <parameter>string</parameter> must be valid in this encoding.
1379 </entry>
1380 <entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
1381 <entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
1382 </row>
1384 <row>
1385 <entry>
1386 <literal><function>convert_to</function>(<parameter>string</parameter> <type>text</type>,
1387 <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1388 </entry>
1389 <entry><type>text</type></entry>
1390 <entry>
1391 Convert string to <parameter>dest_encoding</parameter>.
1392 </entry>
1393 <entry><literal>convert_to('some text', 'UTF8')</literal></entry>
1394 <entry><literal>some text</literal> represented in the UTF8 encoding</entry>
1395 </row>
1397 <row>
1398 <entry>
1399 <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
1400 <parameter>type</parameter> <type>text</type>)</literal>
1401 </entry>
1402 <entry><type>bytea</type></entry>
1403 <entry>
1404 Decode binary data from <parameter>string</parameter> previously
1405 encoded with <function>encode</>. Parameter type is same as in <function>encode</>.
1406 </entry>
1407 <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
1408 <entry><literal>123\000\001</literal></entry>
1409 </row>
1411 <row>
1412 <entry>
1413 <literal><function>encode</function>(<parameter>data</parameter> <type>bytea</type>,
1414 <parameter>type</parameter> <type>text</type>)</literal>
1415 </entry>
1416 <entry><type>text</type></entry>
1417 <entry>
1418 Encode binary data to different representation. Supported
1419 types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
1420 <literal>Escape</> merely outputs null bytes as <literal>\000</> and
1421 doubles backslashes.
1422 </entry>
1423 <entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
1424 <entry><literal>MTIzAAE=</literal></entry>
1425 </row>
1427 <row>
1428 <entry><literal><function>initcap</function>(<parameter>string</parameter>)</literal></entry>
1429 <entry><type>text</type></entry>
1430 <entry>
1431 Convert the first letter of each word to uppercase and the
1432 rest to lowercase. Words are sequences of alphanumeric
1433 characters separated by non-alphanumeric characters.
1434 </entry>
1435 <entry><literal>initcap('hi THOMAS')</literal></entry>
1436 <entry><literal>Hi Thomas</literal></entry>
1437 </row>
1439 <row>
1440 <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
1441 <entry><type>int</type></entry>
1442 <entry>
1443 Number of characters in <parameter>string</parameter>
1444 </entry>
1445 <entry><literal>length('jose')</literal></entry>
1446 <entry><literal>4</literal></entry>
1447 </row>
1449 <row>
1450 <entry><literal><function>length</function>(<parameter>string</parameter><type>bytea</type>,
1451 <parameter>encoding</parameter> <type>name</type> )</literal></entry>
1452 <entry><type>int</type></entry>
1453 <entry>
1454 Number of characters in <parameter>string</parameter> in the given
1455 <parameter>encoding</parameter>. The <parameter>string</parameter>
1456 must be valid in this encoding.
1457 </entry>
1458 <entry><literal>length('jose', 'UTF8')</literal></entry>
1459 <entry><literal>4</literal></entry>
1460 </row>
1462 <row>
1463 <entry>
1464 <literal><function>lpad</function>(<parameter>string</parameter> <type>text</type>,
1465 <parameter>length</parameter> <type>int</type>
1466 <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1467 </entry>
1468 <entry><type>text</type></entry>
1469 <entry>
1470 Fill up the <parameter>string</parameter> to length
1471 <parameter>length</parameter> by prepending the characters
1472 <parameter>fill</parameter> (a space by default). If the
1473 <parameter>string</parameter> is already longer than
1474 <parameter>length</parameter> then it is truncated (on the
1475 right).
1476 </entry>
1477 <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
1478 <entry><literal>xyxhi</literal></entry>
1479 </row>
1481 <row>
1482 <entry><literal><function>ltrim</function>(<parameter>string</parameter> <type>text</type>
1483 <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
1484 </entry>
1485 <entry><type>text</type></entry>
1486 <entry>
1487 Remove the longest string containing only characters from
1488 <parameter>characters</parameter> (a space by default) from the start of
1489 <parameter>string</parameter>
1490 </entry>
1491 <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
1492 <entry><literal>trim</literal></entry>
1493 </row>
1495 <row>
1496 <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
1497 <entry><type>text</type></entry>
1498 <entry>
1499 Calculates the MD5 hash of <parameter>string</parameter>,
1500 returning the result in hexadecimal
1501 </entry>
1502 <entry><literal>md5('abc')</literal></entry>
1503 <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
1504 </row>
1506 <row>
1507 <entry><literal><function>pg_client_encoding</function>()</literal></entry>
1508 <entry><type>name</type></entry>
1509 <entry>
1510 Current client encoding name
1511 </entry>
1512 <entry><literal>pg_client_encoding()</literal></entry>
1513 <entry><literal>SQL_ASCII</literal></entry>
1514 </row>
1516 <row>
1517 <entry><literal><function>quote_ident</function>(<parameter>string</parameter>)</literal></entry>
1518 <entry><type>text</type></entry>
1519 <entry>
1520 Return the given string suitably quoted to be used as an identifier
1521 in an <acronym>SQL</acronym> statement string.
1522 Quotes are added only if necessary (i.e., if the string contains
1523 non-identifier characters or would be case-folded).
1524 Embedded quotes are properly doubled.
1525 </entry>
1526 <entry><literal>quote_ident('Foo bar')</literal></entry>
1527 <entry><literal>"Foo bar"</literal></entry>
1528 </row>
1530 <row>
1531 <entry><literal><function>quote_literal</function>(<parameter>string</parameter>)</literal></entry>
1532 <entry><type>text</type></entry>
1533 <entry>
1534 Return the given string suitably quoted to be used as a string literal
1535 in an <acronym>SQL</acronym> statement string.
1536 Embedded single-quotes and backslashes are properly doubled.
1537 </entry>
1538 <entry><literal>quote_literal('O\'Reilly')</literal></entry>
1539 <entry><literal>'O''Reilly'</literal></entry>
1540 </row>
1542 <row>
1543 <entry><literal><function>regexp_matches</function>(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</literal></entry>
1544 <entry><type>setof text[]</type></entry>
1545 <entry>
1546 Return all captured substrings resulting from matching a POSIX regular
1547 expression against the <parameter>string</parameter>. See
1548 <xref linkend="functions-posix-regexp"> for more information.
1549 </entry>
1550 <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
1551 <entry><literal>{bar,beque}</literal></entry>
1552 </row>
1554 <row>
1555 <entry><literal><function>regexp_replace</function>(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</literal></entry>
1556 <entry><type>text</type></entry>
1557 <entry>
1558 Replace substring(s) matching a POSIX regular expression. See
1559 <xref linkend="functions-posix-regexp"> for more information.
1560 </entry>
1561 <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
1562 <entry><literal>ThM</literal></entry>
1563 </row>
1565 <row>
1566 <entry><literal><function>regexp_split_to_array</function>(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ])</literal></entry>
1567 <entry><type>text[]</type></entry>
1568 <entry>
1569 Split <parameter>string</parameter> using a POSIX regular expression as
1570 the delimiter. See <xref linkend="functions-posix-regexp"> for more
1571 information.
1572 </entry>
1573 <entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
1574 <entry><literal>{hello,world}</literal></entry>
1575 </row>
1577 <row>
1578 <entry><literal><function>regexp_split_to_table</function>(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</literal></entry>
1579 <entry><type>setof text</type></entry>
1580 <entry>
1581 Split <parameter>string</parameter> using a POSIX regular expression as
1582 the delimiter. See <xref linkend="functions-posix-regexp"> for more
1583 information.
1584 </entry>
1585 <entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
1586 <entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
1587 </row>
1589 <row>
1590 <entry><literal><function>repeat</function>(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</literal></entry>
1591 <entry><type>text</type></entry>
1592 <entry>Repeat <parameter>string</parameter> the specified
1593 <parameter>number</parameter> of times</entry>
1594 <entry><literal>repeat('Pg', 4)</literal></entry>
1595 <entry><literal>PgPgPgPg</literal></entry>
1596 </row>
1598 <row>
1599 <entry><literal><function>replace</function>(<parameter>string</parameter> <type>text</type>,
1600 <parameter>from</parameter> <type>text</type>,
1601 <parameter>to</parameter> <type>text</type>)</literal></entry>
1602 <entry><type>text</type></entry>
1603 <entry>Replace all occurrences in <parameter>string</parameter> of substring
1604 <parameter>from</parameter> with substring <parameter>to</parameter>
1605 </entry>
1606 <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
1607 <entry><literal>abXXefabXXef</literal></entry>
1608 </row>
1610 <row>
1611 <entry>
1612 <literal><function>rpad</function>(<parameter>string</parameter> <type>text</type>,
1613 <parameter>length</parameter> <type>int</type>
1614 <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1615 </entry>
1616 <entry><type>text</type></entry>
1617 <entry>
1618 Fill up the <parameter>string</parameter> to length
1619 <parameter>length</parameter> by appending the characters
1620 <parameter>fill</parameter> (a space by default). If the
1621 <parameter>string</parameter> is already longer than
1622 <parameter>length</parameter> then it is truncated.
1623 </entry>
1624 <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
1625 <entry><literal>hixyx</literal></entry>
1626 </row>
1628 <row>
1629 <entry><literal><function>rtrim</function>(<parameter>string</parameter> <type>text</type>
1630 <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
1631 </entry>
1632 <entry><type>text</type></entry>
1633 <entry>
1634 Remove the longest string containing only characters from
1635 <parameter>characters</parameter> (a space by default) from the end of
1636 <parameter>string</parameter>
1637 </entry>
1638 <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
1639 <entry><literal>trim</literal></entry>
1640 </row>
1642 <row>
1643 <entry><literal><function>split_part</function>(<parameter>string</parameter> <type>text</type>,
1644 <parameter>delimiter</parameter> <type>text</type>,
1645 <parameter>field</parameter> <type>int</type>)</literal></entry>
1646 <entry><type>text</type></entry>
1647 <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1648 and return the given field (counting from one)
1649 </entry>
1650 <entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
1651 <entry><literal>def</literal></entry>
1652 </row>
1654 <row>
1655 <entry><literal><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</literal></entry>
1656 <entry><type>int</type></entry>
1657 <entry>
1658 Location of specified substring (same as
1659 <literal>position(<parameter>substring</parameter> in
1660 <parameter>string</parameter>)</literal>, but note the reversed
1661 argument order)
1662 </entry>
1663 <entry><literal>strpos('high', 'ig')</literal></entry>
1664 <entry><literal>2</literal></entry>
1665 </row>
1667 <row>
1668 <entry><literal><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</literal></entry>
1669 <entry><type>text</type></entry>
1670 <entry>
1671 Extract substring (same as
1672 <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
1673 </entry>
1674 <entry><literal>substr('alphabet', 3, 2)</literal></entry>
1675 <entry><literal>ph</literal></entry>
1676 </row>
1678 <row>
1679 <entry><literal><function>to_ascii</function>(<parameter>string</parameter> <type>text</type>
1680 <optional>, <parameter>encoding</parameter> <type>text</type></optional>)</literal></entry>
1681 <entry><type>text</type></entry>
1683 <entry>
1684 Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
1685 (only supports conversion from <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
1686 and <literal>WIN1250</> encodings)
1687 </entry>
1689 <entry><literal>to_ascii('Karel')</literal></entry>
1690 <entry><literal>Karel</literal></entry>
1691 </row>
1693 <row>
1694 <entry><literal><function>to_hex</function>(<parameter>number</parameter> <type>int</type>
1695 or <type>bigint</type>)</literal></entry>
1696 <entry><type>text</type></entry>
1697 <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
1698 representation
1699 </entry>
1700 <entry><literal>to_hex(2147483647)</literal></entry>
1701 <entry><literal>7fffffff</literal></entry>
1702 </row>
1704 <row>
1705 <entry>
1706 <literal><function>translate</function>(<parameter>string</parameter> <type>text</type>,
1707 <parameter>from</parameter> <type>text</type>,
1708 <parameter>to</parameter> <type>text</type>)</literal>
1709 </entry>
1710 <entry><type>text</type></entry>
1711 <entry>
1712 Any character in <parameter>string</parameter> that matches a
1713 character in the <parameter>from</parameter> set is replaced by
1714 the corresponding character in the <parameter>to</parameter>
1716 </entry>
1717 <entry><literal>translate('12345', '14', 'ax')</literal></entry>
1718 <entry><literal>a23x5</literal></entry>
1719 </row>
1721 </tbody>
1722 </tgroup>
1723 </table>
1726 <table id="conversion-names">
1727 <title>Built-in Conversions</title>
1728 <tgroup cols="3">
1729 <thead>
1730 <row>
1731 <entry>Conversion Name
1732 <footnote>
1733 <para>
1734 The conversion names follow a standard naming scheme: The
1735 official name of the source encoding with all
1736 non-alphanumeric characters replaced by underscores followed
1737 by <literal>_to_</literal> followed by the equally processed
1738 destination encoding name. Therefore the names might deviate
1739 from the customary encoding names.
1740 </para>
1741 </footnote>
1742 </entry>
1743 <entry>Source Encoding</entry>
1744 <entry>Destination Encoding</entry>
1745 </row>
1746 </thead>
1748 <tbody>
1749 <row>
1750 <entry><literal>ascii_to_mic</literal></entry>
1751 <entry><literal>SQL_ASCII</literal></entry>
1752 <entry><literal>MULE_INTERNAL</literal></entry>
1753 </row>
1755 <row>
1756 <entry><literal>ascii_to_utf8</literal></entry>
1757 <entry><literal>SQL_ASCII</literal></entry>
1758 <entry><literal>UTF8</literal></entry>
1759 </row>
1761 <row>
1762 <entry><literal>big5_to_euc_tw</literal></entry>
1763 <entry><literal>BIG5</literal></entry>
1764 <entry><literal>EUC_TW</literal></entry>
1765 </row>
1767 <row>
1768 <entry><literal>big5_to_mic</literal></entry>
1769 <entry><literal>BIG5</literal></entry>
1770 <entry><literal>MULE_INTERNAL</literal></entry>
1771 </row>
1773 <row>
1774 <entry><literal>big5_to_utf8</literal></entry>
1775 <entry><literal>BIG5</literal></entry>
1776 <entry><literal>UTF8</literal></entry>
1777 </row>
1779 <row>
1780 <entry><literal>euc_cn_to_mic</literal></entry>
1781 <entry><literal>EUC_CN</literal></entry>
1782 <entry><literal>MULE_INTERNAL</literal></entry>
1783 </row>
1785 <row>
1786 <entry><literal>euc_cn_to_utf8</literal></entry>
1787 <entry><literal>EUC_CN</literal></entry>
1788 <entry><literal>UTF8</literal></entry>
1789 </row>
1791 <row>
1792 <entry><literal>euc_jp_to_mic</literal></entry>
1793 <entry><literal>EUC_JP</literal></entry>
1794 <entry><literal>MULE_INTERNAL</literal></entry>
1795 </row>
1797 <row>
1798 <entry><literal>euc_jp_to_sjis</literal></entry>
1799 <entry><literal>EUC_JP</literal></entry>
1800 <entry><literal>SJIS</literal></entry>
1801 </row>
1803 <row>
1804 <entry><literal>euc_jp_to_utf8</literal></entry>
1805 <entry><literal>EUC_JP</literal></entry>
1806 <entry><literal>UTF8</literal></entry>
1807 </row>
1809 <row>
1810 <entry><literal>euc_kr_to_mic</literal></entry>
1811 <entry><literal>EUC_KR</literal></entry>
1812 <entry><literal>MULE_INTERNAL</literal></entry>
1813 </row>
1815 <row>
1816 <entry><literal>euc_kr_to_utf8</literal></entry>
1817 <entry><literal>EUC_KR</literal></entry>
1818 <entry><literal>UTF8</literal></entry>
1819 </row>
1821 <row>
1822 <entry><literal>euc_tw_to_big5</literal></entry>
1823 <entry><literal>EUC_TW</literal></entry>
1824 <entry><literal>BIG5</literal></entry>
1825 </row>
1827 <row>
1828 <entry><literal>euc_tw_to_mic</literal></entry>
1829 <entry><literal>EUC_TW</literal></entry>
1830 <entry><literal>MULE_INTERNAL</literal></entry>
1831 </row>
1833 <row>
1834 <entry><literal>euc_tw_to_utf8</literal></entry>
1835 <entry><literal>EUC_TW</literal></entry>
1836 <entry><literal>UTF8</literal></entry>
1837 </row>
1839 <row>
1840 <entry><literal>gb18030_to_utf8</literal></entry>
1841 <entry><literal>GB18030</literal></entry>
1842 <entry><literal>UTF8</literal></entry>
1843 </row>
1845 <row>
1846 <entry><literal>gbk_to_utf8</literal></entry>
1847 <entry><literal>GBK</literal></entry>
1848 <entry><literal>UTF8</literal></entry>
1849 </row>
1851 <row>
1852 <entry><literal>iso_8859_10_to_utf8</literal></entry>
1853 <entry><literal>LATIN6</literal></entry>
1854 <entry><literal>UTF8</literal></entry>
1855 </row>
1857 <row>
1858 <entry><literal>iso_8859_13_to_utf8</literal></entry>
1859 <entry><literal>LATIN7</literal></entry>
1860 <entry><literal>UTF8</literal></entry>
1861 </row>
1863 <row>
1864 <entry><literal>iso_8859_14_to_utf8</literal></entry>
1865 <entry><literal>LATIN8</literal></entry>
1866 <entry><literal>UTF8</literal></entry>
1867 </row>
1869 <row>
1870 <entry><literal>iso_8859_15_to_utf8</literal></entry>
1871 <entry><literal>LATIN9</literal></entry>
1872 <entry><literal>UTF8</literal></entry>
1873 </row>
1875 <row>
1876 <entry><literal>iso_8859_16_to_utf8</literal></entry>
1877 <entry><literal>LATIN10</literal></entry>
1878 <entry><literal>UTF8</literal></entry>
1879 </row>
1881 <row>
1882 <entry><literal>iso_8859_1_to_mic</literal></entry>
1883 <entry><literal>LATIN1</literal></entry>
1884 <entry><literal>MULE_INTERNAL</literal></entry>
1885 </row>
1887 <row>
1888 <entry><literal>iso_8859_1_to_utf8</literal></entry>
1889 <entry><literal>LATIN1</literal></entry>
1890 <entry><literal>UTF8</literal></entry>
1891 </row>
1893 <row>
1894 <entry><literal>iso_8859_2_to_mic</literal></entry>
1895 <entry><literal>LATIN2</literal></entry>
1896 <entry><literal>MULE_INTERNAL</literal></entry>
1897 </row>
1899 <row>
1900 <entry><literal>iso_8859_2_to_utf8</literal></entry>
1901 <entry><literal>LATIN2</literal></entry>
1902 <entry><literal>UTF8</literal></entry>
1903 </row>
1905 <row>
1906 <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
1907 <entry><literal>LATIN2</literal></entry>
1908 <entry><literal>WIN1250</literal></entry>
1909 </row>
1911 <row>
1912 <entry><literal>iso_8859_3_to_mic</literal></entry>
1913 <entry><literal>LATIN3</literal></entry>
1914 <entry><literal>MULE_INTERNAL</literal></entry>
1915 </row>
1917 <row>
1918 <entry><literal>iso_8859_3_to_utf8</literal></entry>
1919 <entry><literal>LATIN3</literal></entry>
1920 <entry><literal>UTF8</literal></entry>
1921 </row>
1923 <row>
1924 <entry><literal>iso_8859_4_to_mic</literal></entry>
1925 <entry><literal>LATIN4</literal></entry>
1926 <entry><literal>MULE_INTERNAL</literal></entry>
1927 </row>
1929 <row>
1930 <entry><literal>iso_8859_4_to_utf8</literal></entry>
1931 <entry><literal>LATIN4</literal></entry>
1932 <entry><literal>UTF8</literal></entry>
1933 </row>
1935 <row>
1936 <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
1937 <entry><literal>ISO_8859_5</literal></entry>
1938 <entry><literal>KOI8</literal></entry>
1939 </row>
1941 <row>
1942 <entry><literal>iso_8859_5_to_mic</literal></entry>
1943 <entry><literal>ISO_8859_5</literal></entry>
1944 <entry><literal>MULE_INTERNAL</literal></entry>
1945 </row>
1947 <row>
1948 <entry><literal>iso_8859_5_to_utf8</literal></entry>
1949 <entry><literal>ISO_8859_5</literal></entry>
1950 <entry><literal>UTF8</literal></entry>
1951 </row>
1953 <row>
1954 <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
1955 <entry><literal>ISO_8859_5</literal></entry>
1956 <entry><literal>WIN1251</literal></entry>
1957 </row>
1959 <row>
1960 <entry><literal>iso_8859_5_to_windows_866</literal></entry>
1961 <entry><literal>ISO_8859_5</literal></entry>
1962 <entry><literal>WIN866</literal></entry>
1963 </row>
1965 <row>
1966 <entry><literal>iso_8859_6_to_utf8</literal></entry>
1967 <entry><literal>ISO_8859_6</literal></entry>
1968 <entry><literal>UTF8</literal></entry>
1969 </row>
1971 <row>
1972 <entry><literal>iso_8859_7_to_utf8</literal></entry>
1973 <entry><literal>ISO_8859_7</literal></entry>
1974 <entry><literal>UTF8</literal></entry>
1975 </row>
1977 <row>
1978 <entry><literal>iso_8859_8_to_utf8</literal></entry>
1979 <entry><literal>ISO_8859_8</literal></entry>
1980 <entry><literal>UTF8</literal></entry>
1981 </row>
1983 <row>
1984 <entry><literal>iso_8859_9_to_utf8</literal></entry>
1985 <entry><literal>LATIN5</literal></entry>
1986 <entry><literal>UTF8</literal></entry>
1987 </row>
1989 <row>
1990 <entry><literal>johab_to_utf8</literal></entry>
1991 <entry><literal>JOHAB</literal></entry>
1992 <entry><literal>UTF8</literal></entry>
1993 </row>
1995 <row>
1996 <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
1997 <entry><literal>KOI8</literal></entry>
1998 <entry><literal>ISO_8859_5</literal></entry>
1999 </row>
2001 <row>
2002 <entry><literal>koi8_r_to_mic</literal></entry>
2003 <entry><literal>KOI8</literal></entry>
2004 <entry><literal>MULE_INTERNAL</literal></entry>
2005 </row>
2007 <row>
2008 <entry><literal>koi8_r_to_utf8</literal></entry>
2009 <entry><literal>KOI8</literal></entry>
2010 <entry><literal>UTF8</literal></entry>
2011 </row>
2013 <row>
2014 <entry><literal>koi8_r_to_windows_1251</literal></entry>
2015 <entry><literal>KOI8</literal></entry>
2016 <entry><literal>WIN1251</literal></entry>
2017 </row>
2019 <row>
2020 <entry><literal>koi8_r_to_windows_866</literal></entry>
2021 <entry><literal>KOI8</literal></entry>
2022 <entry><literal>WIN866</literal></entry>
2023 </row>
2025 <row>
2026 <entry><literal>mic_to_ascii</literal></entry>
2027 <entry><literal>MULE_INTERNAL</literal></entry>
2028 <entry><literal>SQL_ASCII</literal></entry>
2029 </row>
2031 <row>
2032 <entry><literal>mic_to_big5</literal></entry>
2033 <entry><literal>MULE_INTERNAL</literal></entry>
2034 <entry><literal>BIG5</literal></entry>
2035 </row>
2037 <row>
2038 <entry><literal>mic_to_euc_cn</literal></entry>
2039 <entry><literal>MULE_INTERNAL</literal></entry>
2040 <entry><literal>EUC_CN</literal></entry>
2041 </row>
2043 <row>
2044 <entry><literal>mic_to_euc_jp</literal></entry>
2045 <entry><literal>MULE_INTERNAL</literal></entry>
2046 <entry><literal>EUC_JP</literal></entry>
2047 </row>
2049 <row>
2050 <entry><literal>mic_to_euc_kr</literal></entry>
2051 <entry><literal>MULE_INTERNAL</literal></entry>
2052 <entry><literal>EUC_KR</literal></entry>
2053 </row>
2055 <row>
2056 <entry><literal>mic_to_euc_tw</literal></entry>
2057 <entry><literal>MULE_INTERNAL</literal></entry>
2058 <entry><literal>EUC_TW</literal></entry>
2059 </row>
2061 <row>
2062 <entry><literal>mic_to_iso_8859_1</literal></entry>
2063 <entry><literal>MULE_INTERNAL</literal></entry>
2064 <entry><literal>LATIN1</literal></entry>
2065 </row>
2067 <row>
2068 <entry><literal>mic_to_iso_8859_2</literal></entry>
2069 <entry><literal>MULE_INTERNAL</literal></entry>
2070 <entry><literal>LATIN2</literal></entry>
2071 </row>
2073 <row>
2074 <entry><literal>mic_to_iso_8859_3</literal></entry>
2075 <entry><literal>MULE_INTERNAL</literal></entry>
2076 <entry><literal>LATIN3</literal></entry>
2077 </row>
2079 <row>
2080 <entry><literal>mic_to_iso_8859_4</literal></entry>
2081 <entry><literal>MULE_INTERNAL</literal></entry>
2082 <entry><literal>LATIN4</literal></entry>
2083 </row>
2085 <row>
2086 <entry><literal>mic_to_iso_8859_5</literal></entry>
2087 <entry><literal>MULE_INTERNAL</literal></entry>
2088 <entry><literal>ISO_8859_5</literal></entry>
2089 </row>
2091 <row>
2092 <entry><literal>mic_to_koi8_r</literal></entry>
2093 <entry><literal>MULE_INTERNAL</literal></entry>
2094 <entry><literal>KOI8</literal></entry>
2095 </row>
2097 <row>
2098 <entry><literal>mic_to_sjis</literal></entry>
2099 <entry><literal>MULE_INTERNAL</literal></entry>
2100 <entry><literal>SJIS</literal></entry>
2101 </row>
2103 <row>
2104 <entry><literal>mic_to_windows_1250</literal></entry>
2105 <entry><literal>MULE_INTERNAL</literal></entry>
2106 <entry><literal>WIN1250</literal></entry>
2107 </row>
2109 <row>
2110 <entry><literal>mic_to_windows_1251</literal></entry>
2111 <entry><literal>MULE_INTERNAL</literal></entry>
2112 <entry><literal>WIN1251</literal></entry>
2113 </row>
2115 <row>
2116 <entry><literal>mic_to_windows_866</literal></entry>
2117 <entry><literal>MULE_INTERNAL</literal></entry>
2118 <entry><literal>WIN866</literal></entry>
2119 </row>
2121 <row>
2122 <entry><literal>sjis_to_euc_jp</literal></entry>
2123 <entry><literal>SJIS</literal></entry>
2124 <entry><literal>EUC_JP</literal></entry>
2125 </row>
2127 <row>
2128 <entry><literal>sjis_to_mic</literal></entry>
2129 <entry><literal>SJIS</literal></entry>
2130 <entry><literal>MULE_INTERNAL</literal></entry>
2131 </row>
2133 <row>
2134 <entry><literal>sjis_to_utf8</literal></entry>
2135 <entry><literal>SJIS</literal></entry>
2136 <entry><literal>UTF8</literal></entry>
2137 </row>
2139 <row>
2140 <entry><literal>tcvn_to_utf8</literal></entry>
2141 <entry><literal>WIN1258</literal></entry>
2142 <entry><literal>UTF8</literal></entry>
2143 </row>
2145 <row>
2146 <entry><literal>uhc_to_utf8</literal></entry>
2147 <entry><literal>UHC</literal></entry>
2148 <entry><literal>UTF8</literal></entry>
2149 </row>
2151 <row>
2152 <entry><literal>utf8_to_ascii</literal></entry>
2153 <entry><literal>UTF8</literal></entry>
2154 <entry><literal>SQL_ASCII</literal></entry>
2155 </row>
2157 <row>
2158 <entry><literal>utf8_to_big5</literal></entry>
2159 <entry><literal>UTF8</literal></entry>
2160 <entry><literal>BIG5</literal></entry>
2161 </row>
2163 <row>
2164 <entry><literal>utf8_to_euc_cn</literal></entry>
2165 <entry><literal>UTF8</literal></entry>
2166 <entry><literal>EUC_CN</literal></entry>
2167 </row>
2169 <row>
2170 <entry><literal>utf8_to_euc_jp</literal></entry>
2171 <entry><literal>UTF8</literal></entry>
2172 <entry><literal>EUC_JP</literal></entry>
2173 </row>
2175 <row>
2176 <entry><literal>utf8_to_euc_kr</literal></entry>
2177 <entry><literal>UTF8</literal></entry>
2178 <entry><literal>EUC_KR</literal></entry>
2179 </row>
2181 <row>
2182 <entry><literal>utf8_to_euc_tw</literal></entry>
2183 <entry><literal>UTF8</literal></entry>
2184 <entry><literal>EUC_TW</literal></entry>
2185 </row>
2187 <row>
2188 <entry><literal>utf8_to_gb18030</literal></entry>
2189 <entry><literal>UTF8</literal></entry>
2190 <entry><literal>GB18030</literal></entry>
2191 </row>
2193 <row>
2194 <entry><literal>utf8_to_gbk</literal></entry>
2195 <entry><literal>UTF8</literal></entry>
2196 <entry><literal>GBK</literal></entry>
2197 </row>
2199 <row>
2200 <entry><literal>utf8_to_iso_8859_1</literal></entry>
2201 <entry><literal>UTF8</literal></entry>
2202 <entry><literal>LATIN1</literal></entry>
2203 </row>
2205 <row>
2206 <entry><literal>utf8_to_iso_8859_10</literal></entry>
2207 <entry><literal>UTF8</literal></entry>
2208 <entry><literal>LATIN6</literal></entry>
2209 </row>
2211 <row>
2212 <entry><literal>utf8_to_iso_8859_13</literal></entry>
2213 <entry><literal>UTF8</literal></entry>
2214 <entry><literal>LATIN7</literal></entry>
2215 </row>
2217 <row>
2218 <entry><literal>utf8_to_iso_8859_14</literal></entry>
2219 <entry><literal>UTF8</literal></entry>
2220 <entry><literal>LATIN8</literal></entry>
2221 </row>
2223 <row>
2224 <entry><literal>utf8_to_iso_8859_15</literal></entry>
2225 <entry><literal>UTF8</literal></entry>
2226 <entry><literal>LATIN9</literal></entry>
2227 </row>
2229 <row>
2230 <entry><literal>utf8_to_iso_8859_16</literal></entry>
2231 <entry><literal>UTF8</literal></entry>
2232 <entry><literal>LATIN10</literal></entry>
2233 </row>
2235 <row>
2236 <entry><literal>utf8_to_iso_8859_2</literal></entry>
2237 <entry><literal>UTF8</literal></entry>
2238 <entry><literal>LATIN2</literal></entry>
2239 </row>
2241 <row>
2242 <entry><literal>utf8_to_iso_8859_3</literal></entry>
2243 <entry><literal>UTF8</literal></entry>
2244 <entry><literal>LATIN3</literal></entry>
2245 </row>
2247 <row>
2248 <entry><literal>utf8_to_iso_8859_4</literal></entry>
2249 <entry><literal>UTF8</literal></entry>
2250 <entry><literal>LATIN4</literal></entry>
2251 </row>
2253 <row>
2254 <entry><literal>utf8_to_iso_8859_5</literal></entry>
2255 <entry><literal>UTF8</literal></entry>
2256 <entry><literal>ISO_8859_5</literal></entry>
2257 </row>
2259 <row>
2260 <entry><literal>utf8_to_iso_8859_6</literal></entry>
2261 <entry><literal>UTF8</literal></entry>
2262 <entry><literal>ISO_8859_6</literal></entry>
2263 </row>
2265 <row>
2266 <entry><literal>utf8_to_iso_8859_7</literal></entry>
2267 <entry><literal>UTF8</literal></entry>
2268 <entry><literal>ISO_8859_7</literal></entry>
2269 </row>
2271 <row>
2272 <entry><literal>utf8_to_iso_8859_8</literal></entry>
2273 <entry><literal>UTF8</literal></entry>
2274 <entry><literal>ISO_8859_8</literal></entry>
2275 </row>
2277 <row>
2278 <entry><literal>utf8_to_iso_8859_9</literal></entry>
2279 <entry><literal>UTF8</literal></entry>
2280 <entry><literal>LATIN5</literal></entry>
2281 </row>
2283 <row>
2284 <entry><literal>utf8_to_johab</literal></entry>
2285 <entry><literal>UTF8</literal></entry>
2286 <entry><literal>JOHAB</literal></entry>
2287 </row>
2289 <row>
2290 <entry><literal>utf8_to_koi8_r</literal></entry>
2291 <entry><literal>UTF8</literal></entry>
2292 <entry><literal>KOI8</literal></entry>
2293 </row>
2295 <row>
2296 <entry><literal>utf8_to_sjis</literal></entry>
2297 <entry><literal>UTF8</literal></entry>
2298 <entry><literal>SJIS</literal></entry>
2299 </row>
2301 <row>
2302 <entry><literal>utf8_to_tcvn</literal></entry>
2303 <entry><literal>UTF8</literal></entry>
2304 <entry><literal>WIN1258</literal></entry>
2305 </row>
2307 <row>
2308 <entry><literal>utf8_to_uhc</literal></entry>
2309 <entry><literal>UTF8</literal></entry>
2310 <entry><literal>UHC</literal></entry>
2311 </row>
2313 <row>
2314 <entry><literal>utf8_to_windows_1250</literal></entry>
2315 <entry><literal>UTF8</literal></entry>
2316 <entry><literal>WIN1250</literal></entry>
2317 </row>
2319 <row>
2320 <entry><literal>utf8_to_windows_1251</literal></entry>
2321 <entry><literal>UTF8</literal></entry>
2322 <entry><literal>WIN1251</literal></entry>
2323 </row>
2325 <row>
2326 <entry><literal>utf8_to_windows_1252</literal></entry>
2327 <entry><literal>UTF8</literal></entry>
2328 <entry><literal>WIN1252</literal></entry>
2329 </row>
2331 <row>
2332 <entry><literal>utf8_to_windows_1253</literal></entry>
2333 <entry><literal>UTF8</literal></entry>
2334 <entry><literal>WIN1253</literal></entry>
2335 </row>
2337 <row>
2338 <entry><literal>utf8_to_windows_1254</literal></entry>
2339 <entry><literal>UTF8</literal></entry>
2340 <entry><literal>WIN1254</literal></entry>
2341 </row>
2343 <row>
2344 <entry><literal>utf8_to_windows_1255</literal></entry>
2345 <entry><literal>UTF8</literal></entry>
2346 <entry><literal>WIN1255</literal></entry>
2347 </row>
2349 <row>
2350 <entry><literal>utf8_to_windows_1256</literal></entry>
2351 <entry><literal>UTF8</literal></entry>
2352 <entry><literal>WIN1256</literal></entry>
2353 </row>
2355 <row>
2356 <entry><literal>utf8_to_windows_1257</literal></entry>
2357 <entry><literal>UTF8</literal></entry>
2358 <entry><literal>WIN1257</literal></entry>
2359 </row>
2361 <row>
2362 <entry><literal>utf8_to_windows_866</literal></entry>
2363 <entry><literal>UTF8</literal></entry>
2364 <entry><literal>WIN866</literal></entry>
2365 </row>
2367 <row>
2368 <entry><literal>utf8_to_windows_874</literal></entry>
2369 <entry><literal>UTF8</literal></entry>
2370 <entry><literal>WIN874</literal></entry>
2371 </row>
2373 <row>
2374 <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
2375 <entry><literal>WIN1250</literal></entry>
2376 <entry><literal>LATIN2</literal></entry>
2377 </row>
2379 <row>
2380 <entry><literal>windows_1250_to_mic</literal></entry>
2381 <entry><literal>WIN1250</literal></entry>
2382 <entry><literal>MULE_INTERNAL</literal></entry>
2383 </row>
2385 <row>
2386 <entry><literal>windows_1250_to_utf8</literal></entry>
2387 <entry><literal>WIN1250</literal></entry>
2388 <entry><literal>UTF8</literal></entry>
2389 </row>
2391 <row>
2392 <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
2393 <entry><literal>WIN1251</literal></entry>
2394 <entry><literal>ISO_8859_5</literal></entry>
2395 </row>
2397 <row>
2398 <entry><literal>windows_1251_to_koi8_r</literal></entry>
2399 <entry><literal>WIN1251</literal></entry>
2400 <entry><literal>KOI8</literal></entry>
2401 </row>
2403 <row>
2404 <entry><literal>windows_1251_to_mic</literal></entry>
2405 <entry><literal>WIN1251</literal></entry>
2406 <entry><literal>MULE_INTERNAL</literal></entry>
2407 </row>
2409 <row>
2410 <entry><literal>windows_1251_to_utf8</literal></entry>
2411 <entry><literal>WIN1251</literal></entry>
2412 <entry><literal>UTF8</literal></entry>
2413 </row>
2415 <row>
2416 <entry><literal>windows_1251_to_windows_866</literal></entry>
2417 <entry><literal>WIN1251</literal></entry>
2418 <entry><literal>WIN866</literal></entry>
2419 </row>
2421 <row>
2422 <entry><literal>windows_1252_to_utf8</literal></entry>
2423 <entry><literal>WIN1252</literal></entry>
2424 <entry><literal>UTF8</literal></entry>
2425 </row>
2427 <row>
2428 <entry><literal>windows_1256_to_utf8</literal></entry>
2429 <entry><literal>WIN1256</literal></entry>
2430 <entry><literal>UTF8</literal></entry>
2431 </row>
2433 <row>
2434 <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2435 <entry><literal>WIN866</literal></entry>
2436 <entry><literal>ISO_8859_5</literal></entry>
2437 </row>
2439 <row>
2440 <entry><literal>windows_866_to_koi8_r</literal></entry>
2441 <entry><literal>WIN866</literal></entry>
2442 <entry><literal>KOI8</literal></entry>
2443 </row>
2445 <row>
2446 <entry><literal>windows_866_to_mic</literal></entry>
2447 <entry><literal>WIN866</literal></entry>
2448 <entry><literal>MULE_INTERNAL</literal></entry>
2449 </row>
2451 <row>
2452 <entry><literal>windows_866_to_utf8</literal></entry>
2453 <entry><literal>WIN866</literal></entry>
2454 <entry><literal>UTF8</literal></entry>
2455 </row>
2457 <row>
2458 <entry><literal>windows_866_to_windows_1251</literal></entry>
2459 <entry><literal>WIN866</literal></entry>
2460 <entry><literal>WIN</literal></entry>
2461 </row>
2463 <row>
2464 <entry><literal>windows_874_to_utf8</literal></entry>
2465 <entry><literal>WIN874</literal></entry>
2466 <entry><literal>UTF8</literal></entry>
2467 </row>
2469 <row>
2470 <entry><literal>euc_jis_2004_to_utf8</literal></entry>
2471 <entry><literal>EUC_JIS_2004</literal></entry>
2472 <entry><literal>UTF8</literal></entry>
2473 </row>
2475 <row>
2476 <entry><literal>ut8_to_euc_jis_2004</literal></entry>
2477 <entry><literal>UTF8</literal></entry>
2478 <entry><literal>EUC_JIS_2004</literal></entry>
2479 </row>
2481 <row>
2482 <entry><literal>shift_jis_2004_to_utf8</literal></entry>
2483 <entry><literal>SHIFT_JIS_2004</literal></entry>
2484 <entry><literal>UTF8</literal></entry>
2485 </row>
2487 <row>
2488 <entry><literal>ut8_to_shift_jis_2004</literal></entry>
2489 <entry><literal>UTF8</literal></entry>
2490 <entry><literal>SHIFT_JIS_2004</literal></entry>
2491 </row>
2493 <row>
2494 <entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
2495 <entry><literal>EUC_JIS_2004</literal></entry>
2496 <entry><literal>SHIFT_JIS_2004</literal></entry>
2497 </row>
2499 <row>
2500 <entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
2501 <entry><literal>SHIFT_JIS_2004</literal></entry>
2502 <entry><literal>EUC_JIS_2004</literal></entry>
2503 </row>
2505 </tbody>
2506 </tgroup>
2507 </table>
2509 </sect1>
2512 <sect1 id="functions-binarystring">
2513 <title>Binary String Functions and Operators</title>
2515 <indexterm zone="functions-binarystring">
2516 <primary>binary data</primary>
2517 <secondary>functions</secondary>
2518 </indexterm>
2520 <para>
2521 This section describes functions and operators for examining and
2522 manipulating values of type <type>bytea</type>.
2523 </para>
2525 <para>
2526 <acronym>SQL</acronym> defines some string functions with a
2527 special syntax where
2528 certain key words rather than commas are used to separate the
2529 arguments. Details are in
2530 <xref linkend="functions-binarystring-sql">.
2531 Some functions are also implemented using the regular syntax for
2532 function invocation.
2533 (See <xref linkend="functions-binarystring-other">.)
2534 </para>
2536 <table id="functions-binarystring-sql">
2537 <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
2538 <tgroup cols="5">
2539 <thead>
2540 <row>
2541 <entry>Function</entry>
2542 <entry>Return Type</entry>
2543 <entry>Description</entry>
2544 <entry>Example</entry>
2545 <entry>Result</entry>
2546 </row>
2547 </thead>
2549 <tbody>
2550 <row>
2551 <entry><literal><parameter>string</parameter> <literal>||</literal>
2552 <parameter>string</parameter></literal></entry>
2553 <entry> <type>bytea</type> </entry>
2554 <entry>
2555 String concatenation
2556 <indexterm>
2557 <primary>binary string</primary>
2558 <secondary>concatenation</secondary>
2559 </indexterm>
2560 </entry>
2561 <entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
2562 <entry><literal>\\Post'gres\000</literal></entry>
2563 </row>
2565 <row>
2566 <entry><function>get_bit</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2567 <entry><type>int</type></entry>
2568 <entry>
2569 Extract bit from string
2570 <indexterm>
2571 <primary>get_bit</primary>
2572 </indexterm>
2573 </entry>
2574 <entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
2575 <entry><literal>1</literal></entry>
2576 </row>
2578 <row>
2579 <entry><function>get_byte</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
2580 <entry><type>int</type></entry>
2581 <entry>
2582 Extract byte from string
2583 <indexterm>
2584 <primary>get_byte</primary>
2585 </indexterm>
2586 </entry>
2587 <entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
2588 <entry><literal>109</literal></entry>
2589 </row>
2591 <row>
2592 <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
2593 <entry><type>int</type></entry>
2594 <entry>Number of bytes in binary string</entry>
2595 <entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
2596 <entry><literal>5</literal></entry>
2597 </row>
2599 <row>
2600 <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
2601 <entry><type>int</type></entry>
2602 <entry>Location of specified substring</entry>
2603 <entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
2604 <entry><literal>3</literal></entry>
2605 </row>
2607 <row>
2608 <entry><function>set_bit</function>(<parameter>string</parameter>,
2609 <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2610 <entry><type>bytea</type></entry>
2611 <entry>
2612 Set bit in string
2613 <indexterm>
2614 <primary>set_bit</primary>
2615 </indexterm>
2616 </entry>
2617 <entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
2618 <entry><literal>Th\000omAs</literal></entry>
2619 </row>
2621 <row>
2622 <entry><function>set_byte</function>(<parameter>string</parameter>,
2623 <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2624 <entry><type>bytea</type></entry>
2625 <entry>
2626 Set byte in string
2627 <indexterm>
2628 <primary>set_byte</primary>
2629 </indexterm>
2630 </entry>
2631 <entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
2632 <entry><literal>Th\000o@as</literal></entry>
2633 </row>
2635 <row>
2636 <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</literal></entry>
2637 <entry><type>bytea</type></entry>
2638 <entry>
2639 Extract substring
2640 <indexterm>
2641 <primary>substring</primary>
2642 </indexterm>
2643 </entry>
2644 <entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
2645 <entry><literal>h\000o</literal></entry>
2646 </row>
2648 <row>
2649 <entry>
2650 <literal><function>trim</function>(<optional>both</optional>
2651 <parameter>bytes</parameter> from
2652 <parameter>string</parameter>)</literal>
2653 </entry>
2654 <entry><type>bytea</type></entry>
2655 <entry>
2656 Remove the longest string containing only the bytes in
2657 <parameter>bytes</parameter> from the start
2658 and end of <parameter>string</parameter>
2659 </entry>
2660 <entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
2661 <entry><literal>Tom</literal></entry>
2662 </row>
2663 </tbody>
2664 </tgroup>
2665 </table>
2667 <para>
2668 Additional binary string manipulation functions are available and
2669 are listed in <xref linkend="functions-binarystring-other">. Some
2670 of them are used internally to implement the
2671 <acronym>SQL</acronym>-standard string functions listed in <xref
2672 linkend="functions-binarystring-sql">.
2673 </para>
2675 <table id="functions-binarystring-other">
2676 <title>Other Binary String Functions</title>
2677 <tgroup cols="5">
2678 <thead>
2679 <row>
2680 <entry>Function</entry>
2681 <entry>Return Type</entry>
2682 <entry>Description</entry>
2683 <entry>Example</entry>
2684 <entry>Result</entry>
2685 </row>
2686 </thead>
2688 <tbody>
2689 <row>
2690 <entry><literal><function>btrim</function>(<parameter>string</parameter>
2691 <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</literal></entry>
2692 <entry><type>bytea</type></entry>
2693 <entry>
2694 Remove the longest string consisting only of bytes
2695 in <parameter>bytes</parameter> from the start and end of
2696 <parameter>string</parameter>
2697 </entry>
2698 <entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
2699 <entry><literal>trim</literal></entry>
2700 </row>
2702 <row>
2703 <entry>
2704 <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
2705 <parameter>type</parameter> <type>text</type>)</literal>
2706 </entry>
2707 <entry><type>bytea</type></entry>
2708 <entry>
2709 Decode binary string from <parameter>string</parameter> previously
2710 encoded with <function>encode</>. Parameter type is same as in <function>encode</>.
2711 </entry>
2712 <entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
2713 <entry><literal>123\000456</literal></entry>
2714 </row>
2716 <row>
2717 <entry>
2718 <literal><function>encode</function>(<parameter>string</parameter> <type>bytea</type>,
2719 <parameter>type</parameter> <type>text</type>)</literal>
2720 </entry>
2721 <entry><type>text</type></entry>
2722 <entry>
2723 Encode binary string to <acronym>ASCII</acronym>-only representation. Supported
2724 types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
2725 </entry>
2726 <entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
2727 <entry><literal>123\000456</literal></entry>
2728 </row>
2730 <row>
2731 <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
2732 <entry><type>int</type></entry>
2733 <entry>
2734 Length of binary string
2735 <indexterm>
2736 <primary>binary string</primary>
2737 <secondary>length</secondary>
2738 </indexterm>
2739 <indexterm>
2740 <primary>length</primary>
2741 <secondary sortas="binary string">of a binary string</secondary>
2742 <see>binary strings, length</see>
2743 </indexterm>
2744 </entry>
2745 <entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
2746 <entry><literal>5</literal></entry>
2747 </row>
2749 <row>
2750 <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
2751 <entry><type>text</type></entry>
2752 <entry>
2753 Calculates the MD5 hash of <parameter>string</parameter>,
2754 returning the result in hexadecimal
2755 </entry>
2756 <entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
2757 <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
2758 </row>
2759 </tbody>
2760 </tgroup>
2761 </table>
2763 </sect1>
2766 <sect1 id="functions-bitstring">
2767 <title>Bit String Functions and Operators</title>
2769 <indexterm zone="functions-bitstring">
2770 <primary>bit strings</primary>
2771 <secondary>functions</secondary>
2772 </indexterm>
2774 <para>
2775 This section describes functions and operators for examining and
2776 manipulating bit strings, that is values of the types
2777 <type>bit</type> and <type>bit varying</type>. Aside from the
2778 usual comparison operators, the operators
2779 shown in <xref linkend="functions-bit-string-op-table"> can be used.
2780 Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
2781 and <literal>#</literal> must be of equal length. When bit
2782 shifting, the original length of the string is preserved, as shown
2783 in the examples.
2784 </para>
2786 <table id="functions-bit-string-op-table">
2787 <title>Bit String Operators</title>
2789 <tgroup cols="4">
2790 <thead>
2791 <row>
2792 <entry>Operator</entry>
2793 <entry>Description</entry>
2794 <entry>Example</entry>
2795 <entry>Result</entry>
2796 </row>
2797 </thead>
2799 <tbody>
2800 <row>
2801 <entry> <literal>||</literal> </entry>
2802 <entry>concatenation</entry>
2803 <entry><literal>B'10001' || B'011'</literal></entry>
2804 <entry><literal>10001011</literal></entry>
2805 </row>
2807 <row>
2808 <entry> <literal>&amp;</literal> </entry>
2809 <entry>bitwise AND</entry>
2810 <entry><literal>B'10001' &amp; B'01101'</literal></entry>
2811 <entry><literal>00001</literal></entry>
2812 </row>
2814 <row>
2815 <entry> <literal>|</literal> </entry>
2816 <entry>bitwise OR</entry>
2817 <entry><literal>B'10001' | B'01101'</literal></entry>
2818 <entry><literal>11101</literal></entry>
2819 </row>
2821 <row>
2822 <entry> <literal>#</literal> </entry>
2823 <entry>bitwise XOR</entry>
2824 <entry><literal>B'10001' # B'01101'</literal></entry>
2825 <entry><literal>11100</literal></entry>
2826 </row>
2828 <row>
2829 <entry> <literal>~</literal> </entry>
2830 <entry>bitwise NOT</entry>
2831 <entry><literal>~ B'10001'</literal></entry>
2832 <entry><literal>01110</literal></entry>
2833 </row>
2835 <row>
2836 <entry> <literal>&lt;&lt;</literal> </entry>
2837 <entry>bitwise shift left</entry>
2838 <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
2839 <entry><literal>01000</literal></entry>
2840 </row>
2842 <row>
2843 <entry> <literal>&gt;&gt;</literal> </entry>
2844 <entry>bitwise shift right</entry>
2845 <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
2846 <entry><literal>00100</literal></entry>
2847 </row>
2848 </tbody>
2849 </tgroup>
2850 </table>
2852 <para>
2853 The following <acronym>SQL</acronym>-standard functions work on bit
2854 strings as well as character strings:
2855 <literal><function>length</function></literal>,
2856 <literal><function>bit_length</function></literal>,
2857 <literal><function>octet_length</function></literal>,
2858 <literal><function>position</function></literal>,
2859 <literal><function>substring</function></literal>.
2860 </para>
2862 <para>
2863 In addition, it is possible to cast integral values to and from type
2864 <type>bit</>.
2865 Some examples:
2866 <programlisting>
2867 44::bit(10) <lineannotation>0000101100</lineannotation>
2868 44::bit(3) <lineannotation>100</lineannotation>
2869 cast(-44 as bit(12)) <lineannotation>111111010100</lineannotation>
2870 '1110'::bit(4)::integer <lineannotation>14</lineannotation>
2871 </programlisting>
2872 Note that casting to just <quote>bit</> means casting to
2873 <literal>bit(1)</>, and so it will deliver only the least significant
2874 bit of the integer.
2875 </para>
2877 <note>
2878 <para>
2879 Prior to <productname>PostgreSQL</productname> 8.0, casting an
2880 integer to <type>bit(n)</> would copy the leftmost <literal>n</>
2881 bits of the integer, whereas now it copies the rightmost <literal>n</>
2882 bits. Also, casting an integer to a bit string width wider than
2883 the integer itself will sign-extend on the left.
2884 </para>
2885 </note>
2887 </sect1>
2890 <sect1 id="functions-matching">
2891 <title>Pattern Matching</title>
2893 <indexterm zone="functions-matching">
2894 <primary>pattern matching</primary>
2895 </indexterm>
2897 <para>
2898 There are three separate approaches to pattern matching provided
2899 by <productname>PostgreSQL</productname>: the traditional
2900 <acronym>SQL</acronym> <function>LIKE</function> operator, the
2901 more recent <function>SIMILAR TO</function> operator (added in
2902 SQL:1999), and <acronym>POSIX</acronym>-style regular
2903 expressions. Aside from the basic <quote>does this string match
2904 this pattern?</> operators, functions are available to extract
2905 or replace matching substrings and to split a string at the matches.
2906 </para>
2908 <tip>
2909 <para>
2910 If you have pattern matching needs that go beyond this,
2911 consider writing a user-defined function in Perl or Tcl.
2912 </para>
2913 </tip>
2915 <sect2 id="functions-like">
2916 <title><function>LIKE</function></title>
2918 <indexterm>
2919 <primary>LIKE</primary>
2920 </indexterm>
2922 <synopsis>
2923 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
2924 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
2925 </synopsis>
2927 <para>
2928 Every <replaceable>pattern</replaceable> defines a set of strings.
2929 The <function>LIKE</function> expression returns true if the
2930 <replaceable>string</replaceable> is contained in the set of
2931 strings represented by <replaceable>pattern</replaceable>. (As
2932 expected, the <function>NOT LIKE</function> expression returns
2933 false if <function>LIKE</function> returns true, and vice versa.
2934 An equivalent expression is
2935 <literal>NOT (<replaceable>string</replaceable> LIKE
2936 <replaceable>pattern</replaceable>)</literal>.)
2937 </para>
2939 <para>
2940 If <replaceable>pattern</replaceable> does not contain percent
2941 signs or underscore, then the pattern only represents the string
2942 itself; in that case <function>LIKE</function> acts like the
2943 equals operator. An underscore (<literal>_</literal>) in
2944 <replaceable>pattern</replaceable> stands for (matches) any single
2945 character; a percent sign (<literal>%</literal>) matches any string
2946 of zero or more characters.
2947 </para>
2949 <para>
2950 Some examples:
2951 <programlisting>
2952 'abc' LIKE 'abc' <lineannotation>true</lineannotation>
2953 'abc' LIKE 'a%' <lineannotation>true</lineannotation>
2954 'abc' LIKE '_b_' <lineannotation>true</lineannotation>
2955 'abc' LIKE 'c' <lineannotation>false</lineannotation>
2956 </programlisting>
2957 </para>
2959 <para>
2960 <function>LIKE</function> pattern matches always cover the entire
2961 string. To match a sequence anywhere within a string, the
2962 pattern must therefore start and end with a percent sign.
2963 </para>
2965 <para>
2966 To match a literal underscore or percent sign without matching
2967 other characters, the respective character in
2968 <replaceable>pattern</replaceable> must be
2969 preceded by the escape character. The default escape
2970 character is the backslash but a different one can be selected by
2971 using the <literal>ESCAPE</literal> clause. To match the escape
2972 character itself, write two escape characters.
2973 </para>
2975 <para>
2976 Note that the backslash already has a special meaning in string literals,
2977 so to write a pattern constant that contains a backslash you must write two
2978 backslashes in an SQL statement (assuming escape string syntax is used, see
2979 <xref linkend="sql-syntax-strings">). Thus, writing a pattern that
2980 actually matches a literal backslash means writing four backslashes in the
2981 statement. You can avoid this by selecting a different escape character
2982 with <literal>ESCAPE</literal>; then a backslash is not special to
2983 <function>LIKE</function> anymore. (But it is still special to the string
2984 literal parser, so you still need two of them.)
2985 </para>
2987 <para>
2988 It's also possible to select no escape character by writing
2989 <literal>ESCAPE ''</literal>. This effectively disables the
2990 escape mechanism, which makes it impossible to turn off the
2991 special meaning of underscore and percent signs in the pattern.
2992 </para>
2994 <para>
2995 The key word <token>ILIKE</token> can be used instead of
2996 <token>LIKE</token> to make the match case-insensitive according
2997 to the active locale. This is not in the <acronym>SQL</acronym> standard but is a
2998 <productname>PostgreSQL</productname> extension.
2999 </para>
3001 <para>
3002 The operator <literal>~~</literal> is equivalent to
3003 <function>LIKE</function>, and <literal>~~*</literal> corresponds to
3004 <function>ILIKE</function>. There are also
3005 <literal>!~~</literal> and <literal>!~~*</literal> operators that
3006 represent <function>NOT LIKE</function> and <function>NOT
3007 ILIKE</function>, respectively. All of these operators are
3008 <productname>PostgreSQL</productname>-specific.
3009 </para>
3010 </sect2>
3013 <sect2 id="functions-similarto-regexp">
3014 <title><function>SIMILAR TO</function> Regular Expressions</title>
3016 <indexterm>
3017 <primary>regular expression</primary>
3018 <!-- <seealso>pattern matching</seealso> breaks index build -->
3019 </indexterm>
3021 <indexterm>
3022 <primary>SIMILAR TO</primary>
3023 </indexterm>
3024 <indexterm>
3025 <primary>substring</primary>
3026 </indexterm>
3028 <synopsis>
3029 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3030 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
3031 </synopsis>
3033 <para>
3034 The <function>SIMILAR TO</function> operator returns true or
3035 false depending on whether its pattern matches the given string.
3036 It is much like <function>LIKE</function>, except that it
3037 interprets the pattern using the SQL standard's definition of a
3038 regular expression. SQL regular expressions are a curious cross
3039 between <function>LIKE</function> notation and common regular
3040 expression notation.
3041 </para>
3043 <para>
3044 Like <function>LIKE</function>, the <function>SIMILAR TO</function>
3045 operator succeeds only if its pattern matches the entire string;
3046 this is unlike common regular expression practice, wherein the pattern
3047 can match any part of the string.
3048 Also like
3049 <function>LIKE</function>, <function>SIMILAR TO</function> uses
3050 <literal>_</> and <literal>%</> as wildcard characters denoting
3051 any single character and any string, respectively (these are
3052 comparable to <literal>.</> and <literal>.*</> in POSIX regular
3053 expressions).
3054 </para>
3056 <para>
3057 In addition to these facilities borrowed from <function>LIKE</function>,
3058 <function>SIMILAR TO</function> supports these pattern-matching
3059 metacharacters borrowed from POSIX regular expressions:
3061 <itemizedlist>
3062 <listitem>
3063 <para>
3064 <literal>|</literal> denotes alternation (either of two alternatives).
3065 </para>
3066 </listitem>
3067 <listitem>
3068 <para>
3069 <literal>*</literal> denotes repetition of the previous item zero
3070 or more times.
3071 </para>
3072 </listitem>
3073 <listitem>
3074 <para>
3075 <literal>+</literal> denotes repetition of the previous item one
3076 or more times.
3077 </para>
3078 </listitem>
3079 <listitem>
3080 <para>
3081 Parentheses <literal>()</literal> can be used to group items into
3082 a single logical item.
3083 </para>
3084 </listitem>
3085 <listitem>
3086 <para>
3087 A bracket expression <literal>[...]</literal> specifies a character
3088 class, just as in POSIX regular expressions.
3089 </para>
3090 </listitem>
3091 </itemizedlist>
3093 Notice that bounded repetition (<literal>?</> and <literal>{...}</>)
3094 are not provided, though they exist in POSIX. Also, the dot (<literal>.</>)
3095 is not a metacharacter.
3096 </para>
3098 <para>
3099 As with <function>LIKE</>, a backslash disables the special meaning
3100 of any of these metacharacters; or a different escape character can
3101 be specified with <literal>ESCAPE</>.
3102 </para>
3104 <para>
3105 Some examples:
3106 <programlisting>
3107 'abc' SIMILAR TO 'abc' <lineannotation>true</lineannotation>
3108 'abc' SIMILAR TO 'a' <lineannotation>false</lineannotation>
3109 'abc' SIMILAR TO '%(b|d)%' <lineannotation>true</lineannotation>
3110 'abc' SIMILAR TO '(b|c)%' <lineannotation>false</lineannotation>
3111 </programlisting>
3112 </para>
3114 <para>
3115 The <function>substring</> function with three parameters,
3116 <function>substring(<replaceable>string</replaceable> from
3117 <replaceable>pattern</replaceable> for
3118 <replaceable>escape-character</replaceable>)</function>, provides
3119 extraction of a substring that matches an SQL
3120 regular expression pattern. As with <literal>SIMILAR TO</>, the
3121 specified pattern must match to the entire data string, else the
3122 function fails and returns null. To indicate the part of the
3123 pattern that should be returned on success, the pattern must contain
3124 two occurrences of the escape character followed by a double quote
3125 (<literal>"</>). The text matching the portion of the pattern
3126 between these markers is returned.
3127 </para>
3129 <para>
3130 Some examples:
3131 <programlisting>
3132 substring('foobar' from '%#"o_b#"%' for '#') <lineannotation>oob</lineannotation>
3133 substring('foobar' from '#"o_b#"%' for '#') <lineannotation>NULL</lineannotation>
3134 </programlisting>
3135 </para>
3136 </sect2>
3138 <sect2 id="functions-posix-regexp">
3139 <title><acronym>POSIX</acronym> Regular Expressions</title>
3141 <indexterm zone="functions-posix-regexp">
3142 <primary>regular expression</primary>
3143 <seealso>pattern matching</seealso>
3144 </indexterm>
3145 <indexterm>
3146 <primary>substring</primary>
3147 </indexterm>
3148 <indexterm>
3149 <primary>regexp_replace</primary>
3150 </indexterm>
3151 <indexterm>
3152 <primary>regexp_matches</primary>
3153 </indexterm>
3154 <indexterm>
3155 <primary>regexp_split_to_table</primary>
3156 </indexterm>
3157 <indexterm>
3158 <primary>regexp_split_to_array</primary>
3159 </indexterm>
3161 <para>
3162 <xref linkend="functions-posix-table"> lists the available
3163 operators for pattern matching using POSIX regular expressions.
3164 </para>
3166 <table id="functions-posix-table">
3167 <title>Regular Expression Match Operators</title>
3169 <tgroup cols="3">
3170 <thead>
3171 <row>
3172 <entry>Operator</entry>
3173 <entry>Description</entry>
3174 <entry>Example</entry>
3175 </row>
3176 </thead>
3178 <tbody>
3179 <row>
3180 <entry> <literal>~</literal> </entry>
3181 <entry>Matches regular expression, case sensitive</entry>
3182 <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3183 </row>
3185 <row>
3186 <entry> <literal>~*</literal> </entry>
3187 <entry>Matches regular expression, case insensitive</entry>
3188 <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3189 </row>
3191 <row>
3192 <entry> <literal>!~</literal> </entry>
3193 <entry>Does not match regular expression, case sensitive</entry>
3194 <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3195 </row>
3197 <row>
3198 <entry> <literal>!~*</literal> </entry>
3199 <entry>Does not match regular expression, case insensitive</entry>
3200 <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3201 </row>
3202 </tbody>
3203 </tgroup>
3204 </table>
3206 <para>
3207 <acronym>POSIX</acronym> regular expressions provide a more
3208 powerful means for
3209 pattern matching than the <function>LIKE</function> and
3210 <function>SIMILAR TO</> operators.
3211 Many Unix tools such as <command>egrep</command>,
3212 <command>sed</command>, or <command>awk</command> use a pattern
3213 matching language that is similar to the one described here.
3214 </para>
3216 <para>
3217 A regular expression is a character sequence that is an
3218 abbreviated definition of a set of strings (a <firstterm>regular
3219 set</firstterm>). A string is said to match a regular expression
3220 if it is a member of the regular set described by the regular
3221 expression. As with <function>LIKE</function>, pattern characters
3222 match string characters exactly unless they are special characters
3223 in the regular expression language &mdash; but regular expressions use
3224 different special characters than <function>LIKE</function> does.
3225 Unlike <function>LIKE</function> patterns, a
3226 regular expression is allowed to match anywhere within a string, unless
3227 the regular expression is explicitly anchored to the beginning or
3228 end of the string.
3229 </para>
3231 <para>
3232 Some examples:
3233 <programlisting>
3234 'abc' ~ 'abc' <lineannotation>true</lineannotation>
3235 'abc' ~ '^a' <lineannotation>true</lineannotation>
3236 'abc' ~ '(b|d)' <lineannotation>true</lineannotation>
3237 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3238 </programlisting>
3239 </para>
3241 <para>
3242 The <acronym>POSIX</acronym> pattern language is described in much
3243 greater detail below.
3244 </para>
3246 <para>
3247 The <function>substring</> function with two parameters,
3248 <function>substring(<replaceable>string</replaceable> from
3249 <replaceable>pattern</replaceable>)</function>, provides extraction of a
3250 substring
3251 that matches a POSIX regular expression pattern. It returns null if
3252 there is no match, otherwise the portion of the text that matched the
3253 pattern. But if the pattern contains any parentheses, the portion
3254 of the text that matched the first parenthesized subexpression (the
3255 one whose left parenthesis comes first) is
3256 returned. You can put parentheses around the whole expression
3257 if you want to use parentheses within it without triggering this
3258 exception. If you need parentheses in the pattern before the
3259 subexpression you want to extract, see the non-capturing parentheses
3260 described below.
3261 </para>
3263 <para>
3264 Some examples:
3265 <programlisting>
3266 substring('foobar' from 'o.b') <lineannotation>oob</lineannotation>
3267 substring('foobar' from 'o(.)b') <lineannotation>o</lineannotation>
3268 </programlisting>
3269 </para>
3271 <para>
3272 The <function>regexp_replace</> function provides substitution of
3273 new text for substrings that match POSIX regular expression patterns.
3274 It has the syntax
3275 <function>regexp_replace</function>(<replaceable>source</>,
3276 <replaceable>pattern</>, <replaceable>replacement</>
3277 <optional>, <replaceable>flags</> </optional>).
3278 The <replaceable>source</> string is returned unchanged if
3279 there is no match to the <replaceable>pattern</>. If there is a
3280 match, the <replaceable>source</> string is returned with the
3281 <replaceable>replacement</> string substituted for the matching
3282 substring. The <replaceable>replacement</> string can contain
3283 <literal>\</><replaceable>n</>, where <replaceable>n</> is <literal>1</>
3284 through <literal>9</>, to indicate that the source substring matching the
3285 <replaceable>n</>'th parenthesized subexpression of the pattern should be
3286 inserted, and it can contain <literal>\&amp;</> to indicate that the
3287 substring matching the entire pattern should be inserted. Write
3288 <literal>\\</> if you need to put a literal backslash in the replacement
3289 text. (As always, remember to double backslashes written in literal
3290 constant strings, assuming escape string syntax is used.)
3291 The <replaceable>flags</> parameter is an optional text
3292 string containing zero or more single-letter flags that change the
3293 function's behavior. Flag <literal>i</> specifies case-insensitive
3294 matching, while flag <literal>g</> specifies replacement of each matching
3295 substring rather than only the first one. Other supported flags are
3296 described in <xref linkend="posix-embedded-options-table">.
3297 </para>
3299 <para>
3300 Some examples:
3301 <programlisting>
3302 regexp_replace('foobarbaz', 'b..', 'X')
3303 <lineannotation>fooXbaz</lineannotation>
3304 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3305 <lineannotation>fooXX</lineannotation>
3306 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3307 <lineannotation>fooXarYXazY</lineannotation>
3308 </programlisting>
3309 </para>
3311 <para>
3312 The <function>regexp_matches</> function returns all of the captured
3313 substrings resulting from matching a POSIX regular expression pattern.
3314 It has the syntax
3315 <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3316 <optional>, <replaceable>flags</> </optional>).
3317 If there is no match to the <replaceable>pattern</>, the function returns
3318 no rows. If there is a match, the function returns a text array whose
3319 <replaceable>n</>'th element is the substring matching the
3320 <replaceable>n</>'th parenthesized subexpression of the pattern
3321 (not counting <quote>non-capturing</> parentheses; see below for
3322 details). If the pattern does not contain any parenthesized
3323 subexpressions, then the result is a single-element text array containing
3324 the substring matching the whole pattern.
3325 The <replaceable>flags</> parameter is an optional text
3326 string containing zero or more single-letter flags that change the
3327 function's behavior. Flag <literal>g</> causes the function to find
3328 each match in the string, not only the first one, and return a row for
3329 each such match. Other supported
3330 flags are described in <xref linkend="posix-embedded-options-table">.
3331 </para>
3333 <para>
3334 Some examples:
3335 <programlisting>
3336 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3337 regexp_matches
3338 ----------------
3339 {bar,beque}
3340 (1 row)
3342 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3343 regexp_matches
3344 ----------------
3345 {bar,beque}
3346 {bazil,barf}
3347 (2 rows)
3349 SELECT regexp_matches('foobarbequebaz', 'barbeque');
3350 regexp_matches
3351 ----------------
3352 {barbeque}
3353 (1 row)
3354 </programlisting>
3355 </para>
3357 <para>
3358 The <function>regexp_split_to_table</> function splits a string using a POSIX
3359 regular expression pattern as a delimiter. It has the syntax
3360 <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
3361 <optional>, <replaceable>flags</> </optional>).
3362 If there is no match to the <replaceable>pattern</>, the function returns the
3363 <replaceable>string</>. If there is at least one match, for each match it returns
3364 the text from the end of the last match (or the beginning of the string)
3365 to the beginning of the match. When there are no more matches, it
3366 returns the text from the end of the last match to the end of the string.
3367 The <replaceable>flags</> parameter is an optional text string containing
3368 zero or more single-letter flags that change the function's behavior.
3369 <function>regexp_split_to_table</function> supports the flags described in
3370 <xref linkend="posix-embedded-options-table">.
3371 </para>
3373 <para>
3374 The <function>regexp_split_to_array</> function behaves the same as
3375 <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
3376 returns its result as an array of <type>text</>. It has the syntax
3377 <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
3378 <optional>, <replaceable>flags</> </optional>).
3379 The parameters are the same as for <function>regexp_split_to_table</>.
3380 </para>
3382 <para>
3383 Some examples:
3384 <programlisting>
3386 SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\\s+') AS foo;
3387 foo
3388 --------
3389 the
3390 quick
3391 brown
3392 fox
3393 jumped
3394 over
3395 the
3396 lazy
3397 dog
3398 (9 rows)
3400 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
3401 regexp_split_to_array
3402 ------------------------------------------------
3403 {the,quick,brown,fox,jumped,over,the,lazy,dog}
3404 (1 row)
3406 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
3407 foo
3408 -----
3425 (16 rows)
3426 </programlisting>
3427 </para>
3429 <para>
3430 As the last example demonstrates, the regexp split functions ignore
3431 zero-length matches that occur at the start or end of the string
3432 or immediately after a previous match. This is contrary to the strict
3433 definition of regexp matching that is implemented by
3434 <function>regexp_matches</>, but is usually the most convenient behavior
3435 in practice. Other software systems such as Perl use similar definitions.
3436 </para>
3438 <!-- derived from the re_syntax.n man page -->
3440 <sect3 id="posix-syntax-details">
3441 <title>Regular Expression Details</title>
3443 <para>
3444 <productname>PostgreSQL</productname>'s regular expressions are implemented
3445 using a package written by Henry Spencer. Much of
3446 the description of regular expressions below is copied verbatim from his
3447 manual entry.
3448 </para>
3450 <para>
3451 Regular expressions (<acronym>RE</acronym>s), as defined in
3452 <acronym>POSIX</acronym> 1003.2, come in two forms:
3453 <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
3454 (roughly those of <command>egrep</command>), and
3455 <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
3456 (roughly those of <command>ed</command>).
3457 <productname>PostgreSQL</productname> supports both forms, and
3458 also implements some extensions
3459 that are not in the POSIX standard, but have become widely used anyway
3460 due to their availability in programming languages such as Perl and Tcl.
3461 <acronym>RE</acronym>s using these non-POSIX extensions are called
3462 <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
3463 in this documentation. AREs are almost an exact superset of EREs,
3464 but BREs have several notational incompatibilities (as well as being
3465 much more limited).
3466 We first describe the ARE and ERE forms, noting features that apply
3467 only to AREs, and then describe how BREs differ.
3468 </para>
3470 <note>
3471 <para>
3472 The form of regular expressions accepted by
3473 <productname>PostgreSQL</> can be chosen by setting the <xref
3474 linkend="guc-regex-flavor"> run-time parameter. The usual
3475 setting is <literal>advanced</>, but one might choose
3476 <literal>extended</> for maximum backwards compatibility with
3477 pre-7.4 releases of <productname>PostgreSQL</>.
3478 </para>
3479 </note>
3481 <para>
3482 A regular expression is defined as one or more
3483 <firstterm>branches</firstterm>, separated by
3484 <literal>|</literal>. It matches anything that matches one of the
3485 branches.
3486 </para>
3488 <para>
3489 A branch is zero or more <firstterm>quantified atoms</> or
3490 <firstterm>constraints</>, concatenated.
3491 It matches a match for the first, followed by a match for the second, etc;
3492 an empty branch matches the empty string.
3493 </para>
3495 <para>
3496 A quantified atom is an <firstterm>atom</> possibly followed
3497 by a single <firstterm>quantifier</>.
3498 Without a quantifier, it matches a match for the atom.
3499 With a quantifier, it can match some number of matches of the atom.
3500 An <firstterm>atom</firstterm> can be any of the possibilities
3501 shown in <xref linkend="posix-atoms-table">.
3502 The possible quantifiers and their meanings are shown in
3503 <xref linkend="posix-quantifiers-table">.
3504 </para>
3506 <para>
3507 A <firstterm>constraint</> matches an empty string, but matches only when
3508 specific conditions are met. A constraint can be used where an atom
3509 could be used, except it cannot be followed by a quantifier.
3510 The simple constraints are shown in
3511 <xref linkend="posix-constraints-table">;
3512 some more constraints are described later.
3513 </para>
3516 <table id="posix-atoms-table">
3517 <title>Regular Expression Atoms</title>
3519 <tgroup cols="2">
3520 <thead>
3521 <row>
3522 <entry>Atom</entry>
3523 <entry>Description</entry>
3524 </row>
3525 </thead>
3527 <tbody>
3528 <row>
3529 <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3530 <entry> (where <replaceable>re</> is any regular expression)
3531 matches a match for
3532 <replaceable>re</>, with the match noted for possible reporting </entry>
3533 </row>
3535 <row>
3536 <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3537 <entry> as above, but the match is not noted for reporting
3538 (a <quote>non-capturing</> set of parentheses)
3539 (AREs only) </entry>
3540 </row>
3542 <row>
3543 <entry> <literal>.</> </entry>
3544 <entry> matches any single character </entry>
3545 </row>
3547 <row>
3548 <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
3549 <entry> a <firstterm>bracket expression</>,
3550 matching any one of the <replaceable>chars</> (see
3551 <xref linkend="posix-bracket-expressions"> for more detail) </entry>
3552 </row>
3554 <row>
3555 <entry> <literal>\</><replaceable>k</> </entry>
3556 <entry> (where <replaceable>k</> is a non-alphanumeric character)
3557 matches that character taken as an ordinary character,
3558 e.g. <literal>\\</> matches a backslash character </entry>
3559 </row>
3561 <row>
3562 <entry> <literal>\</><replaceable>c</> </entry>
3563 <entry> where <replaceable>c</> is alphanumeric
3564 (possibly followed by other characters)
3565 is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
3566 (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
3567 </row>
3569 <row>
3570 <entry> <literal>{</> </entry>
3571 <entry> when followed by a character other than a digit,
3572 matches the left-brace character <literal>{</>;
3573 when followed by a digit, it is the beginning of a
3574 <replaceable>bound</> (see below) </entry>
3575 </row>
3577 <row>
3578 <entry> <replaceable>x</> </entry>
3579 <entry> where <replaceable>x</> is a single character with no other
3580 significance, matches that character </entry>
3581 </row>
3582 </tbody>
3583 </tgroup>
3584 </table>
3586 <para>
3587 An RE cannot end with <literal>\</>.
3588 </para>
3590 <note>
3591 <para>
3592 Remember that the backslash (<literal>\</literal>) already has a special
3593 meaning in <productname>PostgreSQL</> string literals.
3594 To write a pattern constant that contains a backslash,
3595 you must write two backslashes in the statement, assuming escape
3596 string syntax is used (see <xref linkend="sql-syntax-strings">).
3597 </para>
3598 </note>
3600 <table id="posix-quantifiers-table">
3601 <title>Regular Expression Quantifiers</title>
3603 <tgroup cols="2">
3604 <thead>
3605 <row>
3606 <entry>Quantifier</entry>
3607 <entry>Matches</entry>
3608 </row>
3609 </thead>
3611 <tbody>
3612 <row>
3613 <entry> <literal>*</> </entry>
3614 <entry> a sequence of 0 or more matches of the atom </entry>
3615 </row>
3617 <row>
3618 <entry> <literal>+</> </entry>
3619 <entry> a sequence of 1 or more matches of the atom </entry>
3620 </row>
3622 <row>
3623 <entry> <literal>?</> </entry>
3624 <entry> a sequence of 0 or 1 matches of the atom </entry>
3625 </row>
3627 <row>
3628 <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
3629 <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
3630 </row>
3632 <row>
3633 <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
3634 <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
3635 </row>
3637 <row>
3638 <entry>
3639 <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3640 <entry> a sequence of <replaceable>m</> through <replaceable>n</>
3641 (inclusive) matches of the atom; <replaceable>m</> cannot exceed
3642 <replaceable>n</> </entry>
3643 </row>
3645 <row>
3646 <entry> <literal>*?</> </entry>
3647 <entry> non-greedy version of <literal>*</> </entry>
3648 </row>
3650 <row>
3651 <entry> <literal>+?</> </entry>
3652 <entry> non-greedy version of <literal>+</> </entry>
3653 </row>
3655 <row>
3656 <entry> <literal>??</> </entry>
3657 <entry> non-greedy version of <literal>?</> </entry>
3658 </row>
3660 <row>
3661 <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
3662 <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
3663 </row>
3665 <row>
3666 <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
3667 <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
3668 </row>
3670 <row>
3671 <entry>
3672 <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
3673 <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3674 </row>
3675 </tbody>
3676 </tgroup>
3677 </table>
3679 <para>
3680 The forms using <literal>{</><replaceable>...</><literal>}</>
3681 are known as <firstterm>bounds</>.
3682 The numbers <replaceable>m</> and <replaceable>n</> within a bound are
3683 unsigned decimal integers with permissible values from 0 to 255 inclusive.
3684 </para>
3686 <para>
3687 <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
3688 same possibilities as their corresponding normal (<firstterm>greedy</>)
3689 counterparts, but prefer the smallest number rather than the largest
3690 number of matches.
3691 See <xref linkend="posix-matching-rules"> for more detail.
3692 </para>
3694 <note>
3695 <para>
3696 A quantifier cannot immediately follow another quantifier.
3697 A quantifier cannot
3698 begin an expression or subexpression or follow
3699 <literal>^</literal> or <literal>|</literal>.
3700 </para>
3701 </note>
3703 <table id="posix-constraints-table">
3704 <title>Regular Expression Constraints</title>
3706 <tgroup cols="2">
3707 <thead>
3708 <row>
3709 <entry>Constraint</entry>
3710 <entry>Description</entry>
3711 </row>
3712 </thead>
3714 <tbody>
3715 <row>
3716 <entry> <literal>^</> </entry>
3717 <entry> matches at the beginning of the string </entry>
3718 </row>
3720 <row>
3721 <entry> <literal>$</> </entry>
3722 <entry> matches at the end of the string </entry>
3723 </row>
3725 <row>
3726 <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
3727 <entry> <firstterm>positive lookahead</> matches at any point
3728 where a substring matching <replaceable>re</> begins
3729 (AREs only) </entry>
3730 </row>
3732 <row>
3733 <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
3734 <entry> <firstterm>negative lookahead</> matches at any point
3735 where no substring matching <replaceable>re</> begins
3736 (AREs only) </entry>
3737 </row>
3738 </tbody>
3739 </tgroup>
3740 </table>
3742 <para>
3743 Lookahead constraints cannot contain <firstterm>back references</>
3744 (see <xref linkend="posix-escape-sequences">),
3745 and all parentheses within them are considered non-capturing.
3746 </para>
3747 </sect3>
3749 <sect3 id="posix-bracket-expressions">
3750 <title>Bracket Expressions</title>
3752 <para>
3753 A <firstterm>bracket expression</firstterm> is a list of
3754 characters enclosed in <literal>[]</literal>. It normally matches
3755 any single character from the list (but see below). If the list
3756 begins with <literal>^</literal>, it matches any single character
3757 <emphasis>not</> from the rest of the list.
3758 If two characters
3759 in the list are separated by <literal>-</literal>, this is
3760 shorthand for the full range of characters between those two
3761 (inclusive) in the collating sequence,
3762 e.g. <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
3763 any decimal digit. It is illegal for two ranges to share an
3764 endpoint, e.g. <literal>a-c-e</literal>. Ranges are very
3765 collating-sequence-dependent, so portable programs should avoid
3766 relying on them.
3767 </para>
3769 <para>
3770 To include a literal <literal>]</literal> in the list, make it the
3771 first character (following a possible <literal>^</literal>). To
3772 include a literal <literal>-</literal>, make it the first or last
3773 character, or the second endpoint of a range. To use a literal
3774 <literal>-</literal> as the first endpoint of a range, enclose it
3775 in <literal>[.</literal> and <literal>.]</literal> to make it a
3776 collating element (see below). With the exception of these characters,
3777 some combinations using <literal>[</literal>
3778 (see next paragraphs), and escapes (AREs only), all other special
3779 characters lose their special significance within a bracket expression.
3780 In particular, <literal>\</literal> is not special when following
3781 ERE or BRE rules, though it is special (as introducing an escape)
3782 in AREs.
3783 </para>
3785 <para>
3786 Within a bracket expression, a collating element (a character, a
3787 multiple-character sequence that collates as if it were a single
3788 character, or a collating-sequence name for either) enclosed in
3789 <literal>[.</literal> and <literal>.]</literal> stands for the
3790 sequence of characters of that collating element. The sequence is
3791 a single element of the bracket expression's list. A bracket
3792 expression containing a multiple-character collating element can thus
3793 match more than one character, e.g. if the collating sequence
3794 includes a <literal>ch</literal> collating element, then the RE
3795 <literal>[[.ch.]]*c</literal> matches the first five characters of
3796 <literal>chchcc</literal>.
3797 </para>
3799 <note>
3800 <para>
3801 <productname>PostgreSQL</> currently has no multicharacter collating
3802 elements. This information describes possible future behavior.
3803 </para>
3804 </note>
3806 <para>
3807 Within a bracket expression, a collating element enclosed in
3808 <literal>[=</literal> and <literal>=]</literal> is an equivalence
3809 class, standing for the sequences of characters of all collating
3810 elements equivalent to that one, including itself. (If there are
3811 no other equivalent collating elements, the treatment is as if the
3812 enclosing delimiters were <literal>[.</literal> and
3813 <literal>.]</literal>.) For example, if <literal>o</literal> and
3814 <literal>^</literal> are the members of an equivalence class, then
3815 <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
3816 <literal>[o^]</literal> are all synonymous. An equivalence class
3817 cannot be an endpoint of a range.
3818 </para>
3820 <para>
3821 Within a bracket expression, the name of a character class
3822 enclosed in <literal>[:</literal> and <literal>:]</literal> stands
3823 for the list of all characters belonging to that class. Standard
3824 character class names are: <literal>alnum</literal>,
3825 <literal>alpha</literal>, <literal>blank</literal>,
3826 <literal>cntrl</literal>, <literal>digit</literal>,
3827 <literal>graph</literal>, <literal>lower</literal>,
3828 <literal>print</literal>, <literal>punct</literal>,
3829 <literal>space</literal>, <literal>upper</literal>,
3830 <literal>xdigit</literal>. These stand for the character classes
3831 defined in
3832 <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
3833 A locale can provide others. A character class cannot be used as
3834 an endpoint of a range.
3835 </para>
3837 <para>
3838 There are two special cases of bracket expressions: the bracket
3839 expressions <literal>[[:&lt;:]]</literal> and
3840 <literal>[[:&gt;:]]</literal> are constraints,
3841 matching empty strings at the beginning
3842 and end of a word respectively. A word is defined as a sequence
3843 of word characters that is neither preceded nor followed by word
3844 characters. A word character is an <literal>alnum</> character (as
3845 defined by
3846 <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
3847 or an underscore. This is an extension, compatible with but not
3848 specified by <acronym>POSIX</acronym> 1003.2, and should be used with
3849 caution in software intended to be portable to other systems.
3850 The constraint escapes described below are usually preferable (they
3851 are no more standard, but are certainly easier to type).
3852 </para>
3853 </sect3>
3855 <sect3 id="posix-escape-sequences">
3856 <title>Regular Expression Escapes</title>
3858 <para>
3859 <firstterm>Escapes</> are special sequences beginning with <literal>\</>
3860 followed by an alphanumeric character. Escapes come in several varieties:
3861 character entry, class shorthands, constraint escapes, and back references.
3862 A <literal>\</> followed by an alphanumeric character but not constituting
3863 a valid escape is illegal in AREs.
3864 In EREs, there are no escapes: outside a bracket expression,
3865 a <literal>\</> followed by an alphanumeric character merely stands for
3866 that character as an ordinary character, and inside a bracket expression,
3867 <literal>\</> is an ordinary character.
3868 (The latter is the one actual incompatibility between EREs and AREs.)
3869 </para>
3871 <para>
3872 <firstterm>Character-entry escapes</> exist to make it easier to specify
3873 non-printing and otherwise inconvenient characters in REs. They are
3874 shown in <xref linkend="posix-character-entry-escapes-table">.
3875 </para>
3877 <para>
3878 <firstterm>Class-shorthand escapes</> provide shorthands for certain
3879 commonly-used character classes. They are
3880 shown in <xref linkend="posix-class-shorthand-escapes-table">.
3881 </para>
3883 <para>
3884 A <firstterm>constraint escape</> is a constraint,
3885 matching the empty string if specific conditions are met,
3886 written as an escape. They are
3887 shown in <xref linkend="posix-constraint-escapes-table">.
3888 </para>
3890 <para>
3891 A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
3892 same string matched by the previous parenthesized subexpression specified
3893 by the number <replaceable>n</>
3894 (see <xref linkend="posix-constraint-backref-table">). For example,
3895 <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
3896 but not <literal>bc</> or <literal>cb</>.
3897 The subexpression must entirely precede the back reference in the RE.
3898 Subexpressions are numbered in the order of their leading parentheses.
3899 Non-capturing parentheses do not define subexpressions.
3900 </para>
3902 <note>
3903 <para>
3904 Keep in mind that an escape's leading <literal>\</> will need to be
3905 doubled when entering the pattern as an SQL string constant. For example:
3906 <programlisting>
3907 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
3908 </programlisting>
3909 </para>
3910 </note>
3912 <table id="posix-character-entry-escapes-table">
3913 <title>Regular Expression Character-Entry Escapes</title>
3915 <tgroup cols="2">
3916 <thead>
3917 <row>
3918 <entry>Escape</entry>
3919 <entry>Description</entry>
3920 </row>
3921 </thead>
3923 <tbody>
3924 <row>
3925 <entry> <literal>\a</> </entry>
3926 <entry> alert (bell) character, as in C </entry>
3927 </row>
3929 <row>
3930 <entry> <literal>\b</> </entry>
3931 <entry> backspace, as in C </entry>
3932 </row>
3934 <row>
3935 <entry> <literal>\B</> </entry>
3936 <entry> synonym for <literal>\</> to help reduce the need for backslash
3937 doubling </entry>
3938 </row>
3940 <row>
3941 <entry> <literal>\c</><replaceable>X</> </entry>
3942 <entry> (where <replaceable>X</> is any character) the character whose
3943 low-order 5 bits are the same as those of
3944 <replaceable>X</>, and whose other bits are all zero </entry>
3945 </row>
3947 <row>
3948 <entry> <literal>\e</> </entry>
3949 <entry> the character whose collating-sequence name
3950 is <literal>ESC</>,
3951 or failing that, the character with octal value 033 </entry>
3952 </row>
3954 <row>
3955 <entry> <literal>\f</> </entry>
3956 <entry> form feed, as in C </entry>
3957 </row>
3959 <row>
3960 <entry> <literal>\n</> </entry>
3961 <entry> newline, as in C </entry>
3962 </row>
3964 <row>
3965 <entry> <literal>\r</> </entry>
3966 <entry> carriage return, as in C </entry>
3967 </row>
3969 <row>
3970 <entry> <literal>\t</> </entry>
3971 <entry> horizontal tab, as in C </entry>
3972 </row>
3974 <row>
3975 <entry> <literal>\u</><replaceable>wxyz</> </entry>
3976 <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
3977 the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
3978 in the local byte ordering </entry>
3979 </row>
3981 <row>
3982 <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
3983 <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
3984 digits)
3985 reserved for a somewhat-hypothetical Unicode extension to 32 bits
3986 </entry>
3987 </row>
3989 <row>
3990 <entry> <literal>\v</> </entry>
3991 <entry> vertical tab, as in C </entry>
3992 </row>
3994 <row>
3995 <entry> <literal>\x</><replaceable>hhh</> </entry>
3996 <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
3997 digits)
3998 the character whose hexadecimal value is
3999 <literal>0x</><replaceable>hhh</>
4000 (a single character no matter how many hexadecimal digits are used)
4001 </entry>
4002 </row>
4004 <row>
4005 <entry> <literal>\0</> </entry>
4006 <entry> the character whose value is <literal>0</> </entry>
4007 </row>
4009 <row>
4010 <entry> <literal>\</><replaceable>xy</> </entry>
4011 <entry> (where <replaceable>xy</> is exactly two octal digits,
4012 and is not a <firstterm>back reference</>)
4013 the character whose octal value is
4014 <literal>0</><replaceable>xy</> </entry>
4015 </row>
4017 <row>
4018 <entry> <literal>\</><replaceable>xyz</> </entry>
4019 <entry> (where <replaceable>xyz</> is exactly three octal digits,
4020 and is not a <firstterm>back reference</>)
4021 the character whose octal value is
4022 <literal>0</><replaceable>xyz</> </entry>
4023 </row>
4024 </tbody>
4025 </tgroup>
4026 </table>
4028 <para>
4029 Hexadecimal digits are <literal>0</>-<literal>9</>,
4030 <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4031 Octal digits are <literal>0</>-<literal>7</>.
4032 </para>
4034 <para>
4035 The character-entry escapes are always taken as ordinary characters.
4036 For example, <literal>\135</> is <literal>]</> in ASCII, but
4037 <literal>\135</> does not terminate a bracket expression.
4038 </para>
4040 <table id="posix-class-shorthand-escapes-table">
4041 <title>Regular Expression Class-Shorthand Escapes</title>
4043 <tgroup cols="2">
4044 <thead>
4045 <row>
4046 <entry>Escape</entry>
4047 <entry>Description</entry>
4048 </row>
4049 </thead>
4051 <tbody>
4052 <row>
4053 <entry> <literal>\d</> </entry>
4054 <entry> <literal>[[:digit:]]</> </entry>
4055 </row>
4057 <row>
4058 <entry> <literal>\s</> </entry>
4059 <entry> <literal>[[:space:]]</> </entry>
4060 </row>
4062 <row>
4063 <entry> <literal>\w</> </entry>
4064 <entry> <literal>[[:alnum:]_]</>
4065 (note underscore is included) </entry>
4066 </row>
4068 <row>
4069 <entry> <literal>\D</> </entry>
4070 <entry> <literal>[^[:digit:]]</> </entry>
4071 </row>
4073 <row>
4074 <entry> <literal>\S</> </entry>
4075 <entry> <literal>[^[:space:]]</> </entry>
4076 </row>
4078 <row>
4079 <entry> <literal>\W</> </entry>
4080 <entry> <literal>[^[:alnum:]_]</>
4081 (note underscore is included) </entry>
4082 </row>
4083 </tbody>
4084 </tgroup>
4085 </table>
4087 <para>
4088 Within bracket expressions, <literal>\d</>, <literal>\s</>,
4089 and <literal>\w</> lose their outer brackets,
4090 and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4091 (So, for example, <literal>[a-c\d]</> is equivalent to
4092 <literal>[a-c[:digit:]]</>.
4093 Also, <literal>[a-c\D]</>, which is equivalent to
4094 <literal>[a-c^[:digit:]]</>, is illegal.)
4095 </para>
4097 <table id="posix-constraint-escapes-table">
4098 <title>Regular Expression Constraint Escapes</title>
4100 <tgroup cols="2">
4101 <thead>
4102 <row>
4103 <entry>Escape</entry>
4104 <entry>Description</entry>
4105 </row>
4106 </thead>
4108 <tbody>
4109 <row>
4110 <entry> <literal>\A</> </entry>
4111 <entry> matches only at the beginning of the string
4112 (see <xref linkend="posix-matching-rules"> for how this differs from
4113 <literal>^</>) </entry>
4114 </row>
4116 <row>
4117 <entry> <literal>\m</> </entry>
4118 <entry> matches only at the beginning of a word </entry>
4119 </row>
4121 <row>
4122 <entry> <literal>\M</> </entry>
4123 <entry> matches only at the end of a word </entry>
4124 </row>
4126 <row>
4127 <entry> <literal>\y</> </entry>
4128 <entry> matches only at the beginning or end of a word </entry>
4129 </row>
4131 <row>
4132 <entry> <literal>\Y</> </entry>
4133 <entry> matches only at a point that is not the beginning or end of a
4134 word </entry>
4135 </row>
4137 <row>
4138 <entry> <literal>\Z</> </entry>
4139 <entry> matches only at the end of the string
4140 (see <xref linkend="posix-matching-rules"> for how this differs from
4141 <literal>$</>) </entry>
4142 </row>
4143 </tbody>
4144 </tgroup>
4145 </table>
4147 <para>
4148 A word is defined as in the specification of
4149 <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
4150 Constraint escapes are illegal within bracket expressions.
4151 </para>
4153 <table id="posix-constraint-backref-table">
4154 <title>Regular Expression Back References</title>
4156 <tgroup cols="2">
4157 <thead>
4158 <row>
4159 <entry>Escape</entry>
4160 <entry>Description</entry>
4161 </row>
4162 </thead>
4164 <tbody>
4165 <row>
4166 <entry> <literal>\</><replaceable>m</> </entry>
4167 <entry> (where <replaceable>m</> is a nonzero digit)
4168 a back reference to the <replaceable>m</>'th subexpression </entry>
4169 </row>
4171 <row>
4172 <entry> <literal>\</><replaceable>mnn</> </entry>
4173 <entry> (where <replaceable>m</> is a nonzero digit, and
4174 <replaceable>nn</> is some more digits, and the decimal value
4175 <replaceable>mnn</> is not greater than the number of closing capturing
4176 parentheses seen so far)
4177 a back reference to the <replaceable>mnn</>'th subexpression </entry>
4178 </row>
4179 </tbody>
4180 </tgroup>
4181 </table>
4183 <note>
4184 <para>
4185 There is an inherent historical ambiguity between octal character-entry
4186 escapes and back references, which is resolved by heuristics,
4187 as hinted at above.
4188 A leading zero always indicates an octal escape.
4189 A single non-zero digit, not followed by another digit,
4190 is always taken as a back reference.
4191 A multidigit sequence not starting with a zero is taken as a back
4192 reference if it comes after a suitable subexpression
4193 (i.e. the number is in the legal range for a back reference),
4194 and otherwise is taken as octal.
4195 </para>
4196 </note>
4197 </sect3>
4199 <sect3 id="posix-metasyntax">
4200 <title>Regular Expression Metasyntax</title>
4202 <para>
4203 In addition to the main syntax described above, there are some special
4204 forms and miscellaneous syntactic facilities available.
4205 </para>
4207 <para>
4208 Normally the flavor of RE being used is determined by
4209 <varname>regex_flavor</>.
4210 However, this can be overridden by a <firstterm>director</> prefix.
4211 If an RE begins with <literal>***:</>,
4212 the rest of the RE is taken as an ARE regardless of
4213 <varname>regex_flavor</>.
4214 If an RE begins with <literal>***=</>,
4215 the rest of the RE is taken to be a literal string,
4216 with all characters considered ordinary characters.
4217 </para>
4219 <para>
4220 An ARE can begin with <firstterm>embedded options</>:
4221 a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4222 (where <replaceable>xyz</> is one or more alphabetic characters)
4223 specifies options affecting the rest of the RE.
4224 These options override any previously determined options (including
4225 both the RE flavor and case sensitivity).
4226 The available option letters are
4227 shown in <xref linkend="posix-embedded-options-table">.
4228 </para>
4230 <table id="posix-embedded-options-table">
4231 <title>ARE Embedded-Option Letters</title>
4233 <tgroup cols="2">
4234 <thead>
4235 <row>
4236 <entry>Option</entry>
4237 <entry>Description</entry>
4238 </row>
4239 </thead>
4241 <tbody>
4242 <row>
4243 <entry> <literal>b</> </entry>
4244 <entry> rest of RE is a BRE </entry>
4245 </row>
4247 <row>
4248 <entry> <literal>c</> </entry>
4249 <entry> case-sensitive matching (overrides operator type) </entry>
4250 </row>
4252 <row>
4253 <entry> <literal>e</> </entry>
4254 <entry> rest of RE is an ERE </entry>
4255 </row>
4257 <row>
4258 <entry> <literal>i</> </entry>
4259 <entry> case-insensitive matching (see
4260 <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
4261 </row>
4263 <row>
4264 <entry> <literal>m</> </entry>
4265 <entry> historical synonym for <literal>n</> </entry>
4266 </row>
4268 <row>
4269 <entry> <literal>n</> </entry>
4270 <entry> newline-sensitive matching (see
4271 <xref linkend="posix-matching-rules">) </entry>
4272 </row>
4274 <row>
4275 <entry> <literal>p</> </entry>
4276 <entry> partial newline-sensitive matching (see
4277 <xref linkend="posix-matching-rules">) </entry>
4278 </row>
4280 <row>
4281 <entry> <literal>q</> </entry>
4282 <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4283 characters </entry>
4284 </row>
4286 <row>
4287 <entry> <literal>s</> </entry>
4288 <entry> non-newline-sensitive matching (default) </entry>
4289 </row>
4291 <row>
4292 <entry> <literal>t</> </entry>
4293 <entry> tight syntax (default; see below) </entry>
4294 </row>
4296 <row>
4297 <entry> <literal>w</> </entry>
4298 <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4299 (see <xref linkend="posix-matching-rules">) </entry>
4300 </row>
4302 <row>
4303 <entry> <literal>x</> </entry>
4304 <entry> expanded syntax (see below) </entry>
4305 </row>
4306 </tbody>
4307 </tgroup>
4308 </table>
4310 <para>
4311 Embedded options take effect at the <literal>)</> terminating the sequence.
4312 They can appear only at the start of an ARE (after the
4313 <literal>***:</> director if any).
4314 </para>
4316 <para>
4317 In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4318 characters are significant, there is an <firstterm>expanded</> syntax,
4319 available by specifying the embedded <literal>x</> option.
4320 In the expanded syntax,
4321 white-space characters in the RE are ignored, as are
4322 all characters between a <literal>#</>
4323 and the following newline (or the end of the RE). This
4324 permits paragraphing and commenting a complex RE.
4325 There are three exceptions to that basic rule:
4327 <itemizedlist>
4328 <listitem>
4329 <para>
4330 a white-space character or <literal>#</> preceded by <literal>\</> is
4331 retained
4332 </para>
4333 </listitem>
4334 <listitem>
4335 <para>
4336 white space or <literal>#</> within a bracket expression is retained
4337 </para>
4338 </listitem>
4339 <listitem>
4340 <para>
4341 white space and comments cannot appear within multicharacter symbols,
4342 such as <literal>(?:</>
4343 </para>
4344 </listitem>
4345 </itemizedlist>
4347 For this purpose, white-space characters are blank, tab, newline, and
4348 any character that belongs to the <replaceable>space</> character class.
4349 </para>
4351 <para>
4352 Finally, in an ARE, outside bracket expressions, the sequence
4353 <literal>(?#</><replaceable>ttt</><literal>)</>
4354 (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4355 is a comment, completely ignored.
4356 Again, this is not allowed between the characters of
4357 multicharacter symbols, like <literal>(?:</>.
4358 Such comments are more a historical artifact than a useful facility,
4359 and their use is deprecated; use the expanded syntax instead.
4360 </para>
4362 <para>
4363 <emphasis>None</> of these metasyntax extensions is available if
4364 an initial <literal>***=</> director
4365 has specified that the user's input be treated as a literal string
4366 rather than as an RE.
4367 </para>
4368 </sect3>
4370 <sect3 id="posix-matching-rules">
4371 <title>Regular Expression Matching Rules</title>
4373 <para>
4374 In the event that an RE could match more than one substring of a given
4375 string, the RE matches the one starting earliest in the string.
4376 If the RE could match more than one substring starting at that point,
4377 either the longest possible match or the shortest possible match will
4378 be taken, depending on whether the RE is <firstterm>greedy</> or
4379 <firstterm>non-greedy</>.
4380 </para>
4382 <para>
4383 Whether an RE is greedy or not is determined by the following rules:
4384 <itemizedlist>
4385 <listitem>
4386 <para>
4387 Most atoms, and all constraints, have no greediness attribute (because
4388 they cannot match variable amounts of text anyway).
4389 </para>
4390 </listitem>
4391 <listitem>
4392 <para>
4393 Adding parentheses around an RE does not change its greediness.
4394 </para>
4395 </listitem>
4396 <listitem>
4397 <para>
4398 A quantified atom with a fixed-repetition quantifier
4399 (<literal>{</><replaceable>m</><literal>}</>
4401 <literal>{</><replaceable>m</><literal>}?</>)
4402 has the same greediness (possibly none) as the atom itself.
4403 </para>
4404 </listitem>
4405 <listitem>
4406 <para>
4407 A quantified atom with other normal quantifiers (including
4408 <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4409 with <replaceable>m</> equal to <replaceable>n</>)
4410 is greedy (prefers longest match).
4411 </para>
4412 </listitem>
4413 <listitem>
4414 <para>
4415 A quantified atom with a non-greedy quantifier (including
4416 <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4417 with <replaceable>m</> equal to <replaceable>n</>)
4418 is non-greedy (prefers shortest match).
4419 </para>
4420 </listitem>
4421 <listitem>
4422 <para>
4423 A branch &mdash; that is, an RE that has no top-level
4424 <literal>|</> operator &mdash; has the same greediness as the first
4425 quantified atom in it that has a greediness attribute.
4426 </para>
4427 </listitem>
4428 <listitem>
4429 <para>
4430 An RE consisting of two or more branches connected by the
4431 <literal>|</> operator is always greedy.
4432 </para>
4433 </listitem>
4434 </itemizedlist>
4435 </para>
4437 <para>
4438 The above rules associate greediness attributes not only with individual
4439 quantified atoms, but with branches and entire REs that contain quantified
4440 atoms. What that means is that the matching is done in such a way that
4441 the branch, or whole RE, matches the longest or shortest possible
4442 substring <emphasis>as a whole</>. Once the length of the entire match
4443 is determined, the part of it that matches any particular subexpression
4444 is determined on the basis of the greediness attribute of that
4445 subexpression, with subexpressions starting earlier in the RE taking
4446 priority over ones starting later.
4447 </para>
4449 <para>
4450 An example of what this means:
4451 <screen>
4452 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4453 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4454 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4455 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4456 </screen>
4457 In the first case, the RE as a whole is greedy because <literal>Y*</>
4458 is greedy. It can match beginning at the <literal>Y</>, and it matches
4459 the longest possible string starting there, i.e., <literal>Y123</>.
4460 The output is the parenthesized part of that, or <literal>123</>.
4461 In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4462 is non-greedy. It can match beginning at the <literal>Y</>, and it matches
4463 the shortest possible string starting there, i.e., <literal>Y1</>.
4464 The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4465 the decision as to the overall match length; so it is forced to match
4466 just <literal>1</>.
4467 </para>
4469 <para>
4470 In short, when an RE contains both greedy and non-greedy subexpressions,
4471 the total match length is either as long as possible or as short as
4472 possible, according to the attribute assigned to the whole RE. The
4473 attributes assigned to the subexpressions only affect how much of that
4474 match they are allowed to <quote>eat</> relative to each other.
4475 </para>
4477 <para>
4478 The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4479 can be used to force greediness or non-greediness, respectively,
4480 on a subexpression or a whole RE.
4481 </para>
4483 <para>
4484 Match lengths are measured in characters, not collating elements.
4485 An empty string is considered longer than no match at all.
4486 For example:
4487 <literal>bb*</>
4488 matches the three middle characters of <literal>abbbc</>;
4489 <literal>(week|wee)(night|knights)</>
4490 matches all ten characters of <literal>weeknights</>;
4491 when <literal>(.*).*</>
4492 is matched against <literal>abc</> the parenthesized subexpression
4493 matches all three characters; and when
4494 <literal>(a*)*</> is matched against <literal>bc</>
4495 both the whole RE and the parenthesized
4496 subexpression match an empty string.
4497 </para>
4499 <para>
4500 If case-independent matching is specified,
4501 the effect is much as if all case distinctions had vanished from the
4502 alphabet.
4503 When an alphabetic that exists in multiple cases appears as an
4504 ordinary character outside a bracket expression, it is effectively
4505 transformed into a bracket expression containing both cases,
4506 e.g. <literal>x</> becomes <literal>[xX]</>.
4507 When it appears inside a bracket expression, all case counterparts
4508 of it are added to the bracket expression, e.g.
4509 <literal>[x]</> becomes <literal>[xX]</>
4510 and <literal>[^x]</> becomes <literal>[^xX]</>.
4511 </para>
4513 <para>
4514 If newline-sensitive matching is specified, <literal>.</>
4515 and bracket expressions using <literal>^</>
4516 will never match the newline character
4517 (so that matches will never cross newlines unless the RE
4518 explicitly arranges it)
4519 and <literal>^</>and <literal>$</>
4520 will match the empty string after and before a newline
4521 respectively, in addition to matching at beginning and end of string
4522 respectively.
4523 But the ARE escapes <literal>\A</> and <literal>\Z</>
4524 continue to match beginning or end of string <emphasis>only</>.
4525 </para>
4527 <para>
4528 If partial newline-sensitive matching is specified,
4529 this affects <literal>.</> and bracket expressions
4530 as with newline-sensitive matching, but not <literal>^</>
4531 and <literal>$</>.
4532 </para>
4534 <para>
4535 If inverse partial newline-sensitive matching is specified,
4536 this affects <literal>^</> and <literal>$</>
4537 as with newline-sensitive matching, but not <literal>.</>
4538 and bracket expressions.
4539 This isn't very useful but is provided for symmetry.
4540 </para>
4541 </sect3>
4543 <sect3 id="posix-limits-compatibility">
4544 <title>Limits and Compatibility</title>
4546 <para>
4547 No particular limit is imposed on the length of REs in this
4548 implementation. However,
4549 programs intended to be highly portable should not employ REs longer
4550 than 256 bytes,
4551 as a POSIX-compliant implementation can refuse to accept such REs.
4552 </para>
4554 <para>
4555 The only feature of AREs that is actually incompatible with
4556 POSIX EREs is that <literal>\</> does not lose its special
4557 significance inside bracket expressions.
4558 All other ARE features use syntax which is illegal or has
4559 undefined or unspecified effects in POSIX EREs;
4560 the <literal>***</> syntax of directors likewise is outside the POSIX
4561 syntax for both BREs and EREs.
4562 </para>
4564 <para>
4565 Many of the ARE extensions are borrowed from Perl, but some have
4566 been changed to clean them up, and a few Perl extensions are not present.
4567 Incompatibilities of note include <literal>\b</>, <literal>\B</>,
4568 the lack of special treatment for a trailing newline,
4569 the addition of complemented bracket expressions to the things
4570 affected by newline-sensitive matching,
4571 the restrictions on parentheses and back references in lookahead
4572 constraints, and the longest/shortest-match (rather than first-match)
4573 matching semantics.
4574 </para>
4576 <para>
4577 Two significant incompatibilities exist between AREs and the ERE syntax
4578 recognized by pre-7.4 releases of <productname>PostgreSQL</>:
4580 <itemizedlist>
4581 <listitem>
4582 <para>
4583 In AREs, <literal>\</> followed by an alphanumeric character is either
4584 an escape or an error, while in previous releases, it was just another
4585 way of writing the alphanumeric.
4586 This should not be much of a problem because there was no reason to
4587 write such a sequence in earlier releases.
4588 </para>
4589 </listitem>
4590 <listitem>
4591 <para>
4592 In AREs, <literal>\</> remains a special character within
4593 <literal>[]</>, so a literal <literal>\</> within a bracket
4594 expression must be written <literal>\\</>.
4595 </para>
4596 </listitem>
4597 </itemizedlist>
4599 While these differences are unlikely to create a problem for most
4600 applications, you can avoid them if necessary by
4601 setting <varname>regex_flavor</> to <literal>extended</>.
4602 </para>
4603 </sect3>
4605 <sect3 id="posix-basic-regexes">
4606 <title>Basic Regular Expressions</title>
4608 <para>
4609 BREs differ from EREs in several respects.
4610 <literal>|</>, <literal>+</>, and <literal>?</>
4611 are ordinary characters and there is no equivalent
4612 for their functionality.
4613 The delimiters for bounds are
4614 <literal>\{</> and <literal>\}</>,
4615 with <literal>{</> and <literal>}</>
4616 by themselves ordinary characters.
4617 The parentheses for nested subexpressions are
4618 <literal>\(</> and <literal>\)</>,
4619 with <literal>(</> and <literal>)</> by themselves ordinary characters.
4620 <literal>^</> is an ordinary character except at the beginning of the
4621 RE or the beginning of a parenthesized subexpression,
4622 <literal>$</> is an ordinary character except at the end of the
4623 RE or the end of a parenthesized subexpression,
4624 and <literal>*</> is an ordinary character if it appears at the beginning
4625 of the RE or the beginning of a parenthesized subexpression
4626 (after a possible leading <literal>^</>).
4627 Finally, single-digit back references are available, and
4628 <literal>\&lt;</> and <literal>\&gt;</>
4629 are synonyms for
4630 <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
4631 respectively; no other escapes are available.
4632 </para>
4633 </sect3>
4635 <!-- end re_syntax.n man page -->
4637 </sect2>
4638 </sect1>
4641 <sect1 id="functions-formatting">
4642 <title>Data Type Formatting Functions</title>
4644 <indexterm>
4645 <primary>formatting</primary>
4646 </indexterm>
4648 <indexterm>
4649 <primary>to_char</primary>
4650 </indexterm>
4651 <indexterm>
4652 <primary>to_date</primary>
4653 </indexterm>
4654 <indexterm>
4655 <primary>to_number</primary>
4656 </indexterm>
4657 <indexterm>
4658 <primary>to_timestamp</primary>
4659 </indexterm>
4661 <para>
4662 The <productname>PostgreSQL</productname> formatting functions
4663 provide a powerful set of tools for converting various data types
4664 (date/time, integer, floating point, numeric) to formatted strings
4665 and for converting from formatted strings to specific data types.
4666 <xref linkend="functions-formatting-table"> lists them.
4667 These functions all follow a common calling convention: the first
4668 argument is the value to be formatted and the second argument is a
4669 template that defines the output or input format.
4670 </para>
4671 <para>
4672 The <function>to_timestamp</function> function can also take a single
4673 <type>double precision</type> argument to convert from Unix epoch to
4674 <type>timestamp with time zone</type>.
4675 (<type>Integer</type> Unix epochs are implicitly cast to
4676 <type>double precision</type>.)
4677 </para>
4679 <table id="functions-formatting-table">
4680 <title>Formatting Functions</title>
4681 <tgroup cols="4">
4682 <thead>
4683 <row>
4684 <entry>Function</entry>
4685 <entry>Return Type</entry>
4686 <entry>Description</entry>
4687 <entry>Example</entry>
4688 </row>
4689 </thead>
4690 <tbody>
4691 <row>
4692 <entry><literal><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</literal></entry>
4693 <entry><type>text</type></entry>
4694 <entry>convert time stamp to string</entry>
4695 <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
4696 </row>
4697 <row>
4698 <entry><literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal></entry>
4699 <entry><type>text</type></entry>
4700 <entry>convert interval to string</entry>
4701 <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
4702 </row>
4703 <row>
4704 <entry><literal><function>to_char</function>(<type>int</type>, <type>text</type>)</literal></entry>
4705 <entry><type>text</type></entry>
4706 <entry>convert integer to string</entry>
4707 <entry><literal>to_char(125, '999')</literal></entry>
4708 </row>
4709 <row>
4710 <entry><literal><function>to_char</function>(<type>double precision</type>,
4711 <type>text</type>)</literal></entry>
4712 <entry><type>text</type></entry>
4713 <entry>convert real/double precision to string</entry>
4714 <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
4715 </row>
4716 <row>
4717 <entry><literal><function>to_char</function>(<type>numeric</type>, <type>text</type>)</literal></entry>
4718 <entry><type>text</type></entry>
4719 <entry>convert numeric to string</entry>
4720 <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
4721 </row>
4722 <row>
4723 <entry><literal><function>to_date</function>(<type>text</type>, <type>text</type>)</literal></entry>
4724 <entry><type>date</type></entry>
4725 <entry>convert string to date</entry>
4726 <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4727 </row>
4728 <row>
4729 <entry><literal><function>to_number</function>(<type>text</type>, <type>text</type>)</literal></entry>
4730 <entry><type>numeric</type></entry>
4731 <entry>convert string to numeric</entry>
4732 <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
4733 </row>
4734 <row>
4735 <entry><literal><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</literal></entry>
4736 <entry><type>timestamp with time zone</type></entry>
4737 <entry>convert string to time stamp</entry>
4738 <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
4739 </row>
4740 <row>
4741 <entry><literal><function>to_timestamp</function>(<type>double precision</type>)</literal></entry>
4742 <entry><type>timestamp with time zone</type></entry>
4743 <entry>convert UNIX epoch to time stamp</entry>
4744 <entry><literal>to_timestamp(200120400)</literal></entry>
4745 </row>
4746 </tbody>
4747 </tgroup>
4748 </table>
4750 <para>
4751 In an output template string (for <function>to_char</>), there are certain patterns that are
4752 recognized and replaced with appropriately-formatted data from the value
4753 to be formatted. Any text that is not a template pattern is simply
4754 copied verbatim. Similarly, in an input template string (for anything but <function>to_char</>), template patterns
4755 identify the parts of the input data string to be looked at and the
4756 values to be found there.
4757 </para>
4759 <para>
4760 <xref linkend="functions-formatting-datetime-table"> shows the
4761 template patterns available for formatting date and time values.
4762 </para>
4764 <table id="functions-formatting-datetime-table">
4765 <title>Template Patterns for Date/Time Formatting</title>
4766 <tgroup cols="2">
4767 <thead>
4768 <row>
4769 <entry>Pattern</entry>
4770 <entry>Description</entry>
4771 </row>
4772 </thead>
4773 <tbody>
4774 <row>
4775 <entry><literal>HH</literal></entry>
4776 <entry>hour of day (01-12)</entry>
4777 </row>
4778 <row>
4779 <entry><literal>HH12</literal></entry>
4780 <entry>hour of day (01-12)</entry>
4781 </row>
4782 <row>
4783 <entry><literal>HH24</literal></entry>
4784 <entry>hour of day (00-23)</entry>
4785 </row>
4786 <row>
4787 <entry><literal>MI</literal></entry>
4788 <entry>minute (00-59)</entry>
4789 </row>
4790 <row>
4791 <entry><literal>SS</literal></entry>
4792 <entry>second (00-59)</entry>
4793 </row>
4794 <row>
4795 <entry><literal>MS</literal></entry>
4796 <entry>millisecond (000-999)</entry>
4797 </row>
4798 <row>
4799 <entry><literal>US</literal></entry>
4800 <entry>microsecond (000000-999999)</entry>
4801 </row>
4802 <row>
4803 <entry><literal>SSSS</literal></entry>
4804 <entry>seconds past midnight (0-86399)</entry>
4805 </row>
4806 <row>
4807 <entry><literal>AM</literal> or <literal>A.M.</literal> or
4808 <literal>PM</literal> or <literal>P.M.</literal></entry>
4809 <entry>meridian indicator (uppercase)</entry>
4810 </row>
4811 <row>
4812 <entry><literal>am</literal> or <literal>a.m.</literal> or
4813 <literal>pm</literal> or <literal>p.m.</literal></entry>
4814 <entry>meridian indicator (lowercase)</entry>
4815 </row>
4816 <row>
4817 <entry><literal>Y,YYY</literal></entry>
4818 <entry>year (4 and more digits) with comma</entry>
4819 </row>
4820 <row>
4821 <entry><literal>YYYY</literal></entry>
4822 <entry>year (4 and more digits)</entry>
4823 </row>
4824 <row>
4825 <entry><literal>YYY</literal></entry>
4826 <entry>last 3 digits of year</entry>
4827 </row>
4828 <row>
4829 <entry><literal>YY</literal></entry>
4830 <entry>last 2 digits of year</entry>
4831 </row>
4832 <row>
4833 <entry><literal>Y</literal></entry>
4834 <entry>last digit of year</entry>
4835 </row>
4836 <row>
4837 <entry><literal>IYYY</literal></entry>
4838 <entry>ISO year (4 and more digits)</entry>
4839 </row>
4840 <row>
4841 <entry><literal>IYY</literal></entry>
4842 <entry>last 3 digits of ISO year</entry>
4843 </row>
4844 <row>
4845 <entry><literal>IY</literal></entry>
4846 <entry>last 2 digits of ISO year</entry>
4847 </row>
4848 <row>
4849 <entry><literal>I</literal></entry>
4850 <entry>last digit of ISO year</entry>
4851 </row>
4852 <row>
4853 <entry><literal>BC</literal> or <literal>B.C.</literal> or
4854 <literal>AD</literal> or <literal>A.D.</literal></entry>
4855 <entry>era indicator (uppercase)</entry>
4856 </row>
4857 <row>
4858 <entry><literal>bc</literal> or <literal>b.c.</literal> or
4859 <literal>ad</literal> or <literal>a.d.</literal></entry>
4860 <entry>era indicator (lowercase)</entry>
4861 </row>
4862 <row>
4863 <entry><literal>MONTH</literal></entry>
4864 <entry>full uppercase month name (blank-padded to 9 chars)</entry>
4865 </row>
4866 <row>
4867 <entry><literal>Month</literal></entry>
4868 <entry>full mixed-case month name (blank-padded to 9 chars)</entry>
4869 </row>
4870 <row>
4871 <entry><literal>month</literal></entry>
4872 <entry>full lowercase month name (blank-padded to 9 chars)</entry>
4873 </row>
4874 <row>
4875 <entry><literal>MON</literal></entry>
4876 <entry>abbreviated uppercase month name (3 chars in English, localized lengths vary)</entry>
4877 </row>
4878 <row>
4879 <entry><literal>Mon</literal></entry>
4880 <entry>abbreviated mixed-case month name (3 chars in English, localized lengths vary)</entry>
4881 </row>
4882 <row>
4883 <entry><literal>mon</literal></entry>
4884 <entry>abbreviated lowercase month name (3 chars in English, localized lengths vary)</entry>
4885 </row>
4886 <row>
4887 <entry><literal>MM</literal></entry>
4888 <entry>month number (01-12)</entry>
4889 </row>
4890 <row>
4891 <entry><literal>DAY</literal></entry>
4892 <entry>full uppercase day name (blank-padded to 9 chars)</entry>
4893 </row>
4894 <row>
4895 <entry><literal>Day</literal></entry>
4896 <entry>full mixed-case day name (blank-padded to 9 chars)</entry>
4897 </row>
4898 <row>
4899 <entry><literal>day</literal></entry>
4900 <entry>full lowercase day name (blank-padded to 9 chars)</entry>
4901 </row>
4902 <row>
4903 <entry><literal>DY</literal></entry>
4904 <entry>abbreviated uppercase day name (3 chars in English, localized lengths vary)</entry>
4905 </row>
4906 <row>
4907 <entry><literal>Dy</literal></entry>
4908 <entry>abbreviated mixed-case day name (3 chars in English, localized lengths vary)</entry>
4909 </row>
4910 <row>
4911 <entry><literal>dy</literal></entry>
4912 <entry>abbreviated lowercase day name (3 chars in English, localized lengths vary)</entry>
4913 </row>
4914 <row>
4915 <entry><literal>DDD</literal></entry>
4916 <entry>day of year (001-366)</entry>
4917 </row>
4918 <row>
4919 <entry><literal>IDDD</literal></entry>
4920 <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
4921 </row>
4922 <row>
4923 <entry><literal>DD</literal></entry>
4924 <entry>day of month (01-31)</entry>
4925 </row>
4926 <row>
4927 <entry><literal>D</literal></entry>
4928 <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
4929 </row>
4930 <row>
4931 <entry><literal>ID</literal></entry>
4932 <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
4933 </row>
4934 <row>
4935 <entry><literal>W</literal></entry>
4936 <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
4937 </row>
4938 <row>
4939 <entry><literal>WW</literal></entry>
4940 <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
4941 </row>
4942 <row>
4943 <entry><literal>IW</literal></entry>
4944 <entry>ISO week number of year (1 - 53; the first Thursday of the new year is in week 1.)</entry>
4945 </row>
4946 <row>
4947 <entry><literal>CC</literal></entry>
4948 <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
4949 </row>
4950 <row>
4951 <entry><literal>J</literal></entry>
4952 <entry>Julian Day (days since January 1, 4712 BC at midnight)</entry>
4953 </row>
4954 <row>
4955 <entry><literal>Q</literal></entry>
4956 <entry>quarter</entry>
4957 </row>
4958 <row>
4959 <entry><literal>RM</literal></entry>
4960 <entry>month in Roman numerals (I-XII; I=January) (uppercase)</entry>
4961 </row>
4962 <row>
4963 <entry><literal>rm</literal></entry>
4964 <entry>month in Roman numerals (i-xii; i=January) (lowercase)</entry>
4965 </row>
4966 <row>
4967 <entry><literal>TZ</literal></entry>
4968 <entry>time-zone name (uppercase)</entry>
4969 </row>
4970 <row>
4971 <entry><literal>tz</literal></entry>
4972 <entry>time-zone name (lowercase)</entry>
4973 </row>
4974 </tbody>
4975 </tgroup>
4976 </table>
4978 <para>
4979 Certain modifiers can be applied to any template pattern to alter its
4980 behavior. For example, <literal>FMMonth</literal>
4981 is the <literal>Month</literal> pattern with the
4982 <literal>FM</literal> modifier.
4983 <xref linkend="functions-formatting-datetimemod-table"> shows the
4984 modifier patterns for date/time formatting.
4985 </para>
4987 <table id="functions-formatting-datetimemod-table">
4988 <title>Template Pattern Modifiers for Date/Time Formatting</title>
4989 <tgroup cols="3">
4990 <thead>
4991 <row>
4992 <entry>Modifier</entry>
4993 <entry>Description</entry>
4994 <entry>Example</entry>
4995 </row>
4996 </thead>
4997 <tbody>
4998 <row>
4999 <entry><literal>FM</literal> prefix</entry>
5000 <entry>fill mode (suppress padding blanks and zeroes)</entry>
5001 <entry><literal>FMMonth</literal></entry>
5002 </row>
5003 <row>
5004 <entry><literal>TH</literal> suffix</entry>
5005 <entry>uppercase ordinal number suffix</entry>
5006 <entry><literal>DDTH</literal></entry>
5007 </row>
5008 <row>
5009 <entry><literal>th</literal> suffix</entry>
5010 <entry>lowercase ordinal number suffix</entry>
5011 <entry><literal>DDth</literal></entry>
5012 </row>
5013 <row>
5014 <entry><literal>FX</literal> prefix</entry>
5015 <entry>fixed format global option (see usage notes)</entry>
5016 <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
5017 </row>
5018 <row>
5019 <entry><literal>TM</literal> prefix</entry>
5020 <entry>translation mode (print localized day and month names based on <varname>lc_messages</>)</entry>
5021 <entry><literal>TMMonth</literal></entry>
5022 </row>
5023 <row>
5024 <entry><literal>SP</literal> suffix</entry>
5025 <entry>spell mode (not yet implemented)</entry>
5026 <entry><literal>DDSP</literal></entry>
5027 </row>
5028 </tbody>
5029 </tgroup>
5030 </table>
5032 <para>
5033 Usage notes for date/time formatting:
5035 <itemizedlist>
5036 <listitem>
5037 <para>
5038 <literal>FM</literal> suppresses leading zeroes and trailing blanks
5039 that would otherwise be added to make the output of a pattern be
5040 fixed-width.
5041 </para>
5042 </listitem>
5044 <listitem>
5045 <para>
5046 <literal>TM</literal> does not include trailing blanks.
5047 </para>
5048 </listitem>
5050 <listitem>
5051 <para>
5052 <function>to_timestamp</function> and <function>to_date</function>
5053 skip multiple blank spaces in the input string if the <literal>FX</literal> option
5054 is not used. <literal>FX</literal> must be specified as the first item
5055 in the template. For example
5056 <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> is correct, but
5057 <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error,
5058 because <function>to_timestamp</function> expects one space only.
5059 </para>
5060 </listitem>
5062 <listitem>
5063 <para>
5064 Ordinary text is allowed in <function>to_char</function>
5065 templates and will be output literally. You can put a substring
5066 in double quotes to force it to be interpreted as literal text
5067 even if it contains pattern key words. For example, in
5068 <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
5069 will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5070 will not be.
5071 </para>
5072 </listitem>
5074 <listitem>
5075 <para>
5076 If you want to have a double quote in the output you must
5077 precede it with a backslash, for example <literal>E'\\"YYYY
5078 Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
5079 (Two backslashes are necessary because the backslash already
5080 has a special meaning when using the escape string syntax.)
5081 </para>
5082 </listitem>
5084 <listitem>
5085 <para>
5086 The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5087 <type>date</type> has a restriction if you use a year with more than 4 digits. You must
5088 use some non-digit character or template after <literal>YYYY</literal>,
5089 otherwise the year is always interpreted as 4 digits. For example
5090 (with the year 20000):
5091 <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
5092 interpreted as a 4-digit year; instead use a non-digit
5093 separator after the year, like
5094 <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5095 <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5096 </para>
5097 </listitem>
5099 <listitem>
5100 <para>
5101 In conversions from string to <type>timestamp</type> or
5102 <type>date</type>, the <literal>CC</literal> field is ignored if there
5103 is a <literal>YYY</literal>, <literal>YYYY</literal> or
5104 <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5105 <literal>YY</literal> or <literal>Y</literal> then the year is computed
5106 as <literal>(CC-1)*100+YY</literal>.
5107 </para>
5108 </listitem>
5110 <listitem>
5111 <para>
5112 An ISO week date (as distinct from a Gregorian date) can be specified to <function>to_timestamp</function> and <function>to_date</function> in one of two ways:
5113 <itemizedlist>
5114 <listitem>
5115 <para>
5116 Year, week and weekday, for example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal> returns the date <literal>2006-10-19</literal>. If you omit the weekday it is assumed to be 1 (Monday).
5117 </para>
5118 </listitem>
5119 <listitem>
5120 <para>
5121 Year and day of year, for example <literal>to_date('2006-291', 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5122 </para>
5123 </listitem>
5124 </itemizedlist>
5125 </para>
5126 <para>
5127 Attempting to construct a date using a mixture of ISO week and Gregorian date fields is nonsensical, and could yield unexpected results. In the context of an ISO year, the concept of a 'month' or 'day of month' has no meaning. In the context of a Gregorian year, the ISO week has no meaning. Users should take care to keep Gregorian and ISO date specifications separate.
5128 </para>
5129 </listitem>
5131 <listitem>
5132 <para>
5133 Millisecond (<literal>MS</literal>) and microsecond (<literal>US</literal>)
5134 values in a conversion from string to <type>timestamp</type> are used as part of the
5135 seconds after the decimal point. For example
5136 <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5137 but 300, because the conversion counts it as 12 + 0.3 seconds.
5138 This means for the format <literal>SS:MS</literal>, the input values
5139 <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5140 same number of milliseconds. To get three milliseconds, one must use
5141 <literal>12:003</literal>, which the conversion counts as
5142 12 + 0.003 = 12.003 seconds.
5143 </para>
5145 <para>
5146 Here is a more
5147 complex example:
5148 <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5149 is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5150 1230 microseconds = 2.021230 seconds.
5151 </para>
5152 </listitem>
5154 <listitem>
5155 <para>
5156 <function>to_char(..., 'ID')</function>'s day of the week numbering
5157 matches the <function>extract('isodow', ...)</function> function, but
5158 <function>to_char(..., 'D')</function>'s does not match
5159 <function>extract('dow', ...)</function>'s day numbering.
5160 </para>
5161 </listitem>
5163 <listitem>
5164 <para><function>to_char(interval)</function> formats <literal>HH</> and
5165 <literal>HH12</> as hours in a single day, while <literal>HH24</>
5166 can output hours exceeding a single day, e.g. &gt;24.
5167 </para>
5168 </listitem>
5170 </itemizedlist>
5171 </para>
5173 <para>
5174 <xref linkend="functions-formatting-numeric-table"> shows the
5175 template patterns available for formatting numeric values.
5176 </para>
5178 <table id="functions-formatting-numeric-table">
5179 <title>Template Patterns for Numeric Formatting</title>
5180 <tgroup cols="2">
5181 <thead>
5182 <row>
5183 <entry>Pattern</entry>
5184 <entry>Description</entry>
5185 </row>
5186 </thead>
5187 <tbody>
5188 <row>
5189 <entry><literal>9</literal></entry>
5190 <entry>value with the specified number of digits</entry>
5191 </row>
5192 <row>
5193 <entry><literal>0</literal></entry>
5194 <entry>value with leading zeros</entry>
5195 </row>
5196 <row>
5197 <entry><literal>.</literal> (period)</entry>
5198 <entry>decimal point</entry>
5199 </row>
5200 <row>
5201 <entry><literal>,</literal> (comma)</entry>
5202 <entry>group (thousand) separator</entry>
5203 </row>
5204 <row>
5205 <entry><literal>PR</literal></entry>
5206 <entry>negative value in angle brackets</entry>
5207 </row>
5208 <row>
5209 <entry><literal>S</literal></entry>
5210 <entry>sign anchored to number (uses locale)</entry>
5211 </row>
5212 <row>
5213 <entry><literal>L</literal></entry>
5214 <entry>currency symbol (uses locale)</entry>
5215 </row>
5216 <row>
5217 <entry><literal>D</literal></entry>
5218 <entry>decimal point (uses locale)</entry>
5219 </row>
5220 <row>
5221 <entry><literal>G</literal></entry>
5222 <entry>group separator (uses locale)</entry>
5223 </row>
5224 <row>
5225 <entry><literal>MI</literal></entry>
5226 <entry>minus sign in specified position (if number &lt; 0)</entry>
5227 </row>
5228 <row>
5229 <entry><literal>PL</literal></entry>
5230 <entry>plus sign in specified position (if number &gt; 0)</entry>
5231 </row>
5232 <row>
5233 <entry><literal>SG</literal></entry>
5234 <entry>plus/minus sign in specified position</entry>
5235 </row>
5236 <row>
5237 <entry><literal>RN</literal></entry>
5238 <entry>roman numeral (input between 1 and 3999)</entry>
5239 </row>
5240 <row>
5241 <entry><literal>TH</literal> or <literal>th</literal></entry>
5242 <entry>ordinal number suffix</entry>
5243 </row>
5244 <row>
5245 <entry><literal>V</literal></entry>
5246 <entry>shift specified number of digits (see notes)</entry>
5247 </row>
5248 <row>
5249 <entry><literal>EEEE</literal></entry>
5250 <entry>scientific notation (not implemented yet)</entry>
5251 </row>
5252 </tbody>
5253 </tgroup>
5254 </table>
5256 <para>
5257 Usage notes for numeric formatting:
5259 <itemizedlist>
5260 <listitem>
5261 <para>
5262 A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5263 <literal>MI</literal> is not anchored to
5264 the number; for example,
5265 <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>,
5266 but <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>.
5267 The Oracle implementation does not allow the use of
5268 <literal>MI</literal> ahead of <literal>9</literal>, but rather
5269 requires that <literal>9</literal> precede
5270 <literal>MI</literal>.
5271 </para>
5272 </listitem>
5274 <listitem>
5275 <para>
5276 <literal>9</literal> results in a value with the same number of
5277 digits as there are <literal>9</literal>s. If a digit is
5278 not available it outputs a space.
5279 </para>
5280 </listitem>
5282 <listitem>
5283 <para>
5284 <literal>TH</literal> does not convert values less than zero
5285 and does not convert fractional numbers.
5286 </para>
5287 </listitem>
5289 <listitem>
5290 <para>
5291 <literal>PL</literal>, <literal>SG</literal>, and
5292 <literal>TH</literal> are <productname>PostgreSQL</productname>
5293 extensions.
5294 </para>
5295 </listitem>
5297 <listitem>
5298 <para>
5299 <literal>V</literal> effectively
5300 multiplies the input values by
5301 <literal>10^<replaceable>n</replaceable></literal>, where
5302 <replaceable>n</replaceable> is the number of digits following
5303 <literal>V</literal>.
5304 <function>to_char</function> does not support the use of
5305 <literal>V</literal> combined with a decimal point.
5306 (E.g., <literal>99.9V99</literal> is not allowed.)
5307 </para>
5308 </listitem>
5309 </itemizedlist>
5310 </para>
5312 <para>
5313 <xref linkend="functions-formatting-examples-table"> shows some
5314 examples of the use of the <function>to_char</function> function.
5315 </para>
5317 <table id="functions-formatting-examples-table">
5318 <title><function>to_char</function> Examples</title>
5319 <tgroup cols="2">
5320 <thead>
5321 <row>
5322 <entry>Expression</entry>
5323 <entry>Result</entry>
5324 </row>
5325 </thead>
5326 <tbody>
5327 <row>
5328 <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5329 <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
5330 </row>
5331 <row>
5332 <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
5333 <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
5334 </row>
5335 <row>
5336 <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5337 <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
5338 </row>
5339 <row>
5340 <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5341 <entry><literal>'-.1'</literal></entry>
5342 </row>
5343 <row>
5344 <entry><literal>to_char(0.1, '0.9')</literal></entry>
5345 <entry><literal>'&nbsp;0.1'</literal></entry>
5346 </row>
5347 <row>
5348 <entry><literal>to_char(12, '9990999.9')</literal></entry>
5349 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
5350 </row>
5351 <row>
5352 <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5353 <entry><literal>'0012.'</literal></entry>
5354 </row>
5355 <row>
5356 <entry><literal>to_char(485, '999')</literal></entry>
5357 <entry><literal>'&nbsp;485'</literal></entry>
5358 </row>
5359 <row>
5360 <entry><literal>to_char(-485, '999')</literal></entry>
5361 <entry><literal>'-485'</literal></entry>
5362 </row>
5363 <row>
5364 <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
5365 <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
5366 </row>
5367 <row>
5368 <entry><literal>to_char(1485, '9,999')</literal></entry>
5369 <entry><literal>'&nbsp;1,485'</literal></entry>
5370 </row>
5371 <row>
5372 <entry><literal>to_char(1485, '9G999')</literal></entry>
5373 <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
5374 </row>
5375 <row>
5376 <entry><literal>to_char(148.5, '999.999')</literal></entry>
5377 <entry><literal>'&nbsp;148.500'</literal></entry>
5378 </row>
5379 <row>
5380 <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5381 <entry><literal>'148.5'</literal></entry>
5382 </row>
5383 <row>
5384 <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5385 <entry><literal>'148.500'</literal></entry>
5386 </row>
5387 <row>
5388 <entry><literal>to_char(148.5, '999D999')</literal></entry>
5389 <entry><literal>'&nbsp;148,500'</literal></entry>
5390 </row>
5391 <row>
5392 <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5393 <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
5394 </row>
5395 <row>
5396 <entry><literal>to_char(-485, '999S')</literal></entry>
5397 <entry><literal>'485-'</literal></entry>
5398 </row>
5399 <row>
5400 <entry><literal>to_char(-485, '999MI')</literal></entry>
5401 <entry><literal>'485-'</literal></entry>
5402 </row>
5403 <row>
5404 <entry><literal>to_char(485, '999MI')</literal></entry>
5405 <entry><literal>'485&nbsp;'</literal></entry>
5406 </row>
5407 <row>
5408 <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5409 <entry><literal>'485'</literal></entry>
5410 </row>
5411 <row>
5412 <entry><literal>to_char(485, 'PL999')</literal></entry>
5413 <entry><literal>'+485'</literal></entry>
5414 </row>
5415 <row>
5416 <entry><literal>to_char(485, 'SG999')</literal></entry>
5417 <entry><literal>'+485'</literal></entry>
5418 </row>
5419 <row>
5420 <entry><literal>to_char(-485, 'SG999')</literal></entry>
5421 <entry><literal>'-485'</literal></entry>
5422 </row>
5423 <row>
5424 <entry><literal>to_char(-485, '9SG99')</literal></entry>
5425 <entry><literal>'4-85'</literal></entry>
5426 </row>
5427 <row>
5428 <entry><literal>to_char(-485, '999PR')</literal></entry>
5429 <entry><literal>'&lt;485&gt;'</literal></entry>
5430 </row>
5431 <row>
5432 <entry><literal>to_char(485, 'L999')</literal></entry>
5433 <entry><literal>'DM&nbsp;485</literal></entry>
5434 </row>
5435 <row>
5436 <entry><literal>to_char(485, 'RN')</literal></entry>
5437 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
5438 </row>
5439 <row>
5440 <entry><literal>to_char(485, 'FMRN')</literal></entry>
5441 <entry><literal>'CDLXXXV'</literal></entry>
5442 </row>
5443 <row>
5444 <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5445 <entry><literal>'V'</literal></entry>
5446 </row>
5447 <row>
5448 <entry><literal>to_char(482, '999th')</literal></entry>
5449 <entry><literal>'&nbsp;482nd'</literal></entry>
5450 </row>
5451 <row>
5452 <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
5453 <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
5454 </row>
5455 <row>
5456 <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
5457 <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
5458 </row>
5459 <row>
5460 <entry><literal>to_char(12, '99V999')</literal></entry>
5461 <entry><literal>'&nbsp;12000'</literal></entry>
5462 </row>
5463 <row>
5464 <entry><literal>to_char(12.4, '99V999')</literal></entry>
5465 <entry><literal>'&nbsp;12400'</literal></entry>
5466 </row>
5467 <row>
5468 <entry><literal>to_char(12.45, '99V9')</literal></entry>
5469 <entry><literal>'&nbsp;125'</literal></entry>
5470 </row>
5471 </tbody>
5472 </tgroup>
5473 </table>
5475 </sect1>
5478 <sect1 id="functions-datetime">
5479 <title>Date/Time Functions and Operators</title>
5481 <para>
5482 <xref linkend="functions-datetime-table"> shows the available
5483 functions for date/time value processing, with details appearing in
5484 the following subsections. <xref
5485 linkend="operators-datetime-table"> illustrates the behaviors of
5486 the basic arithmetic operators (<literal>+</literal>,
5487 <literal>*</literal>, etc.). For formatting functions, refer to
5488 <xref linkend="functions-formatting">. You should be familiar with
5489 the background information on date/time data types from <xref
5490 linkend="datatype-datetime">.
5491 </para>
5493 <para>
5494 All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
5495 inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
5496 with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
5497 For brevity, these variants are not shown separately. Also, the
5498 <literal>+</> and <literal>*</> operators come in commutative pairs (for
5499 example both date + integer and integer + date); we show only one of each
5500 such pair.
5501 </para>
5503 <table id="operators-datetime-table">
5504 <title>Date/Time Operators</title>
5506 <tgroup cols="3">
5507 <thead>
5508 <row>
5509 <entry>Operator</entry>
5510 <entry>Example</entry>
5511 <entry>Result</entry>
5512 </row>
5513 </thead>
5515 <tbody>
5516 <row>
5517 <entry> <literal>+</literal> </entry>
5518 <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
5519 <entry><literal>date '2001-10-05'</literal></entry>
5520 </row>
5522 <row>
5523 <entry> <literal>+</literal> </entry>
5524 <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
5525 <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
5526 </row>
5528 <row>
5529 <entry> <literal>+</literal> </entry>
5530 <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
5531 <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
5532 </row>
5534 <row>
5535 <entry> <literal>+</literal> </entry>
5536 <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
5537 <entry><literal>interval '1 day 01:00:00'</literal></entry>
5538 </row>
5540 <row>
5541 <entry> <literal>+</literal> </entry>
5542 <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
5543 <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
5544 </row>
5546 <row>
5547 <entry> <literal>+</literal> </entry>
5548 <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
5549 <entry><literal>time '04:00:00'</literal></entry>
5550 </row>
5552 <row>
5553 <entry> <literal>-</literal> </entry>
5554 <entry><literal>- interval '23 hours'</literal></entry>
5555 <entry><literal>interval '-23:00:00'</literal></entry>
5556 </row>
5558 <row>
5559 <entry> <literal>-</literal> </entry>
5560 <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
5561 <entry><literal>integer '3'</literal></entry>
5562 </row>
5564 <row>
5565 <entry> <literal>-</literal> </entry>
5566 <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
5567 <entry><literal>date '2001-09-24'</literal></entry>
5568 </row>
5570 <row>
5571 <entry> <literal>-</literal> </entry>
5572 <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
5573 <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
5574 </row>
5576 <row>
5577 <entry> <literal>-</literal> </entry>
5578 <entry><literal>time '05:00' - time '03:00'</literal></entry>
5579 <entry><literal>interval '02:00:00'</literal></entry>
5580 </row>
5582 <row>
5583 <entry> <literal>-</literal> </entry>
5584 <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
5585 <entry><literal>time '03:00:00'</literal></entry>
5586 </row>
5588 <row>
5589 <entry> <literal>-</literal> </entry>
5590 <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
5591 <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
5592 </row>
5594 <row>
5595 <entry> <literal>-</literal> </entry>
5596 <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
5597 <entry><literal>interval '1 day -01:00:00'</literal></entry>
5598 </row>
5600 <row>
5601 <entry> <literal>-</literal> </entry>
5602 <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
5603 <entry><literal>interval '1 day 15:00:00'</literal></entry>
5604 </row>
5606 <row>
5607 <entry> <literal>*</literal> </entry>
5608 <entry><literal>900 * interval '1 second'</literal></entry>
5609 <entry><literal>interval '00:15:00'</literal></entry>
5610 </row>
5612 <row>
5613 <entry> <literal>*</literal> </entry>
5614 <entry><literal>21 * interval '1 day'</literal></entry>
5615 <entry><literal>interval '21 days'</literal></entry>
5616 </row>
5618 <row>
5619 <entry> <literal>*</literal> </entry>
5620 <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
5621 <entry><literal>interval '03:30:00'</literal></entry>
5622 </row>
5624 <row>
5625 <entry> <literal>/</literal> </entry>
5626 <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
5627 <entry><literal>interval '00:40:00'</literal></entry>
5628 </row>
5629 </tbody>
5630 </tgroup>
5631 </table>
5633 <indexterm>
5634 <primary>age</primary>
5635 </indexterm>
5636 <indexterm>
5637 <primary>clock_timestamp</primary>
5638 </indexterm>
5639 <indexterm>
5640 <primary>current_date</primary>
5641 </indexterm>
5642 <indexterm>
5643 <primary>current_time</primary>
5644 </indexterm>
5645 <indexterm>
5646 <primary>current_timestamp</primary>
5647 </indexterm>
5648 <indexterm>
5649 <primary>date_part</primary>
5650 </indexterm>
5651 <indexterm>
5652 <primary>date_trunc</primary>
5653 </indexterm>
5654 <indexterm>
5655 <primary>extract</primary>
5656 </indexterm>
5657 <indexterm>
5658 <primary>isfinite</primary>
5659 </indexterm>
5660 <indexterm>
5661 <primary>justify_days</primary>
5662 </indexterm>
5663 <indexterm>
5664 <primary>justify_hours</primary>
5665 </indexterm>
5666 <indexterm>
5667 <primary>justify_interval</primary>
5668 </indexterm>
5669 <indexterm>
5670 <primary>localtime</primary>
5671 </indexterm>
5672 <indexterm>
5673 <primary>localtimestamp</primary>
5674 </indexterm>
5675 <indexterm>
5676 <primary>now</primary>
5677 </indexterm>
5678 <indexterm>
5679 <primary>statement_timestamp</primary>
5680 </indexterm>
5681 <indexterm>
5682 <primary>timeofday</primary>
5683 </indexterm>
5684 <indexterm>
5685 <primary>transaction_timestamp</primary>
5686 </indexterm>
5688 <table id="functions-datetime-table">
5689 <title>Date/Time Functions</title>
5690 <tgroup cols="5">
5691 <thead>
5692 <row>
5693 <entry>Function</entry>
5694 <entry>Return Type</entry>
5695 <entry>Description</entry>
5696 <entry>Example</entry>
5697 <entry>Result</entry>
5698 </row>
5699 </thead>
5701 <tbody>
5702 <row>
5703 <entry><literal><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</literal></entry>
5704 <entry><type>interval</type></entry>
5705 <entry>Subtract arguments, producing a <quote>symbolic</> result that
5706 uses years and months</entry>
5707 <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
5708 <entry><literal>43 years 9 mons 27 days</literal></entry>
5709 </row>
5711 <row>
5712 <entry><literal><function>age</function>(<type>timestamp</type>)</literal></entry>
5713 <entry><type>interval</type></entry>
5714 <entry>Subtract from <function>current_date</function></entry>
5715 <entry><literal>age(timestamp '1957-06-13')</literal></entry>
5716 <entry><literal>43 years 8 mons 3 days</literal></entry>
5717 </row>
5719 <row>
5720 <entry><literal><function>clock_timestamp</function>()</literal></entry>
5721 <entry><type>timestamp with time zone</type></entry>
5722 <entry>Current date and time (changes during statement execution);
5723 see <xref linkend="functions-datetime-current">
5724 </entry>
5725 <entry></entry>
5726 <entry></entry>
5727 </row>
5729 <row>
5730 <entry><literal><function>current_date</function></literal></entry>
5731 <entry><type>date</type></entry>
5732 <entry>Current date;
5733 see <xref linkend="functions-datetime-current">
5734 </entry>
5735 <entry></entry>
5736 <entry></entry>
5737 </row>
5739 <row>
5740 <entry><literal><function>current_time</function></literal></entry>
5741 <entry><type>time with time zone</type></entry>
5742 <entry>Current time of day;
5743 see <xref linkend="functions-datetime-current">
5744 </entry>
5745 <entry></entry>
5746 <entry></entry>
5747 </row>
5749 <row>
5750 <entry><literal><function>current_timestamp</function></literal></entry>
5751 <entry><type>timestamp with time zone</type></entry>
5752 <entry>Current date and time (start of current transaction);
5753 see <xref linkend="functions-datetime-current">
5754 </entry>
5755 <entry></entry>
5756 <entry></entry>
5757 </row>
5759 <row>
5760 <entry><literal><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5761 <entry><type>double precision</type></entry>
5762 <entry>Get subfield (equivalent to <function>extract</function>);
5763 see <xref linkend="functions-datetime-extract">
5764 </entry>
5765 <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5766 <entry><literal>20</literal></entry>
5767 </row>
5769 <row>
5770 <entry><literal><function>date_part</function>(<type>text</type>, <type>interval</type>)</literal></entry>
5771 <entry><type>double precision</type></entry>
5772 <entry>Get subfield (equivalent to
5773 <function>extract</function>); see <xref linkend="functions-datetime-extract">
5774 </entry>
5775 <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
5776 <entry><literal>3</literal></entry>
5777 </row>
5779 <row>
5780 <entry><literal><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5781 <entry><type>timestamp</type></entry>
5782 <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
5783 </entry>
5784 <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5785 <entry><literal>2001-02-16 20:00:00</literal></entry>
5786 </row>
5788 <row>
5789 <entry><literal><function>extract</function>(<parameter>field</parameter> from
5790 <type>timestamp</type>)</literal></entry>
5791 <entry><type>double precision</type></entry>
5792 <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5793 </entry>
5794 <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
5795 <entry><literal>20</literal></entry>
5796 </row>
5798 <row>
5799 <entry><literal><function>extract</function>(<parameter>field</parameter> from
5800 <type>interval</type>)</literal></entry>
5801 <entry><type>double precision</type></entry>
5802 <entry>Get subfield; see <xref linkend="functions-datetime-extract">
5803 </entry>
5804 <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
5805 <entry><literal>3</literal></entry>
5806 </row>
5808 <row>
5809 <entry><literal><function>isfinite</function>(<type>timestamp</type>)</literal></entry>
5810 <entry><type>boolean</type></entry>
5811 <entry>Test for finite time stamp (not equal to infinity)</entry>
5812 <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
5813 <entry><literal>true</literal></entry>
5814 </row>
5816 <row>
5817 <entry><literal><function>isfinite</function>(<type>interval</type>)</literal></entry>
5818 <entry><type>boolean</type></entry>
5819 <entry>Test for finite interval</entry>
5820 <entry><literal>isfinite(interval '4 hours')</literal></entry>
5821 <entry><literal>true</literal></entry>
5822 </row>
5824 <row>
5825 <entry><literal><function>justify_days</function>(<type>interval</type>)</literal></entry>
5826 <entry><type>interval</type></entry>
5827 <entry>Adjust interval so 30-day time periods are represented as months</entry>
5828 <entry><literal>justify_days(interval '30 days')</literal></entry>
5829 <entry><literal>1 month</literal></entry>
5830 </row>
5832 <row>
5833 <entry><literal><function>justify_hours</function>(<type>interval</type>)</literal></entry>
5834 <entry><type>interval</type></entry>
5835 <entry>Adjust interval so 24-hour time periods are represented as days</entry>
5836 <entry><literal>justify_hours(interval '24 hours')</literal></entry>
5837 <entry><literal>1 day</literal></entry>
5838 </row>
5840 <row>
5841 <entry><literal><function>justify_interval</function>(<type>interval</type>)</literal></entry>
5842 <entry><type>interval</type></entry>
5843 <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
5844 <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
5845 <entry><literal>29 days 23:00:00</literal></entry>
5846 </row>
5848 <row>
5849 <entry><literal><function>localtime</function></literal></entry>
5850 <entry><type>time</type></entry>
5851 <entry>Current time of day;
5852 see <xref linkend="functions-datetime-current">
5853 </entry>
5854 <entry></entry>
5855 <entry></entry>
5856 </row>
5858 <row>
5859 <entry><literal><function>localtimestamp</function></literal></entry>
5860 <entry><type>timestamp</type></entry>
5861 <entry>Current date and time (start of current transaction);
5862 see <xref linkend="functions-datetime-current">
5863 </entry>
5864 <entry></entry>
5865 <entry></entry>
5866 </row>
5868 <row>
5869 <entry><literal><function>now</function>()</literal></entry>
5870 <entry><type>timestamp with time zone</type></entry>
5871 <entry>Current date and time (start of current transaction);
5872 see <xref linkend="functions-datetime-current">
5873 </entry>
5874 <entry></entry>
5875 <entry></entry>
5876 </row>
5878 <row>
5879 <entry><literal><function>statement_timestamp</function>()</literal></entry>
5880 <entry><type>timestamp with time zone</type></entry>
5881 <entry>Current date and time (start of current statement);
5882 see <xref linkend="functions-datetime-current">
5883 </entry>
5884 <entry></entry>
5885 <entry></entry>
5886 </row>
5888 <row>
5889 <entry><literal><function>timeofday</function>()</literal></entry>
5890 <entry><type>text</type></entry>
5891 <entry>Current date and time
5892 (like <function>clock_timestamp</>, but as a <type>text</> string);
5893 see <xref linkend="functions-datetime-current">
5894 </entry>
5895 <entry></entry>
5896 <entry></entry>
5897 </row>
5899 <row>
5900 <entry><literal><function>transaction_timestamp</function>()</literal></entry>
5901 <entry><type>timestamp with time zone</type></entry>
5902 <entry>Current date and time (start of current transaction);
5903 see <xref linkend="functions-datetime-current">
5904 </entry>
5905 <entry></entry>
5906 <entry></entry>
5907 </row>
5908 </tbody>
5909 </tgroup>
5910 </table>
5912 <para>
5913 In addition to these functions, the SQL <literal>OVERLAPS</> operator is
5914 supported:
5915 <synopsis>
5916 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
5917 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
5918 </synopsis>
5919 This expression yields true when two time periods (defined by their
5920 endpoints) overlap, false when they do not overlap. The endpoints
5921 can be specified as pairs of dates, times, or time stamps; or as
5922 a date, time, or time stamp followed by an interval.
5923 </para>
5925 <screen>
5926 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
5927 (DATE '2001-10-30', DATE '2002-10-30');
5928 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
5929 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
5930 (DATE '2001-10-30', DATE '2002-10-30');
5931 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
5932 </screen>
5934 <para>
5935 When adding an <type>interval</type> value to (or subtracting an
5936 <type>interval</type> value from) a <type>timestamp with time zone</type>
5937 value, the days component advances (or decrements) the date of the
5938 <type>timestamp with time zone</type> by the indicated number of days.
5939 Across daylight saving time changes (with the session time zone set to a
5940 time zone that recognizes DST), this means <literal>interval '1 day'</literal>
5941 does not necessarily equal <literal>interval '24 hours'</literal>.
5942 For example, with the session time zone set to <literal>CST7CDT</literal>,
5943 <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
5944 will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>,
5945 while adding <literal>interval '24 hours'</literal> to the same initial
5946 <type>timestamp with time zone</type> produces
5947 <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
5948 a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone
5949 <literal>CST7CDT</literal>.
5950 </para>
5952 <para>
5953 Note there can be ambiguity in the <literal>months</> returned by
5954 <function>age</> because different months have a different number of
5955 days. <productname>PostgreSQL</>'s approach uses the month from the
5956 earlier of the two dates when calculating partial months. For example,
5957 <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
5958 <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
5959 days</> because May has 31 days, while April has only 30.
5960 </para>
5962 <sect2 id="functions-datetime-extract">
5963 <title><function>EXTRACT</function>, <function>date_part</function></title>
5965 <indexterm>
5966 <primary>date_part</primary>
5967 </indexterm>
5968 <indexterm>
5969 <primary>extract</primary>
5970 </indexterm>
5972 <synopsis>
5973 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
5974 </synopsis>
5976 <para>
5977 The <function>extract</function> function retrieves subfields
5978 such as year or hour from date/time values.
5979 <replaceable>source</replaceable> must be a value expression of
5980 type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
5981 (Expressions of type <type>date</type> will
5982 be cast to <type>timestamp</type> and can therefore be used as
5983 well.) <replaceable>field</replaceable> is an identifier or
5984 string that selects what field to extract from the source value.
5985 The <function>extract</function> function returns values of type
5986 <type>double precision</type>.
5987 The following are valid field names:
5989 <!-- alphabetical -->
5990 <variablelist>
5991 <varlistentry>
5992 <term><literal>century</literal></term>
5993 <listitem>
5994 <para>
5995 The century
5996 </para>
5998 <screen>
5999 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6000 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6001 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6002 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6003 </screen>
6005 <para>
6006 The first century starts at 0001-01-01 00:00:00 AD, although
6007 they did not know it at the time. This definition applies to all
6008 Gregorian calendar countries. There is no century number 0,
6009 you go from -1 to 1.
6011 If you disagree with this, please write your complaint to:
6012 Pope, Cathedral Saint-Peter of Roma, Vatican.
6013 </para>
6015 <para>
6016 <productname>PostgreSQL</productname> releases before 8.0 did not
6017 follow the conventional numbering of centuries, but just returned
6018 the year field divided by 100.
6019 </para>
6020 </listitem>
6021 </varlistentry>
6023 <varlistentry>
6024 <term><literal>day</literal></term>
6025 <listitem>
6026 <para>
6027 The day (of the month) field (1 - 31)
6028 </para>
6030 <screen>
6031 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6032 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6033 </screen>
6034 </listitem>
6035 </varlistentry>
6037 <varlistentry>
6038 <term><literal>decade</literal></term>
6039 <listitem>
6040 <para>
6041 The year field divided by 10
6042 </para>
6044 <screen>
6045 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6046 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6047 </screen>
6048 </listitem>
6049 </varlistentry>
6051 <varlistentry>
6052 <term><literal>dow</literal></term>
6053 <listitem>
6054 <para>
6055 The day of the week as Sunday(<literal>0</>) to
6056 Saturday(<literal>6</>)
6057 </para>
6059 <screen>
6060 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6061 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6062 </screen>
6063 <para>
6064 Note that <function>extract</function>'s day of the week numbering
6065 is different from that of the <function>to_char(...,
6066 'D')</function> function.
6067 </para>
6069 </listitem>
6070 </varlistentry>
6072 <varlistentry>
6073 <term><literal>doy</literal></term>
6074 <listitem>
6075 <para>
6076 The day of the year (1 - 365/366)
6077 </para>
6079 <screen>
6080 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6081 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6082 </screen>
6083 </listitem>
6084 </varlistentry>
6086 <varlistentry>
6087 <term><literal>epoch</literal></term>
6088 <listitem>
6089 <para>
6090 For <type>date</type> and <type>timestamp</type> values, the
6091 number of seconds since 1970-01-01 00:00:00-00 (can be negative);
6092 for <type>interval</type> values, the total number
6093 of seconds in the interval
6094 </para>
6096 <screen>
6097 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-08');
6098 <lineannotation>Result: </lineannotation><computeroutput>982384720</computeroutput>
6100 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6101 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6102 </screen>
6104 <para>
6105 Here is how you can convert an epoch value back to a time
6106 stamp:
6107 </para>
6109 <screen>
6110 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720 * INTERVAL '1 second';
6111 </screen>
6112 </listitem>
6113 </varlistentry>
6115 <varlistentry>
6116 <term><literal>hour</literal></term>
6117 <listitem>
6118 <para>
6119 The hour field (0 - 23)
6120 </para>
6122 <screen>
6123 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6124 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6125 </screen>
6126 </listitem>
6127 </varlistentry>
6129 <varlistentry>
6130 <term><literal>isodow</literal></term>
6131 <listitem>
6132 <para>
6133 The day of the week as Monday(<literal>1</>) to
6134 Sunday(<literal>7</>)
6135 </para>
6137 <screen>
6138 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6139 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6140 </screen>
6141 <para>
6142 This is identical to <literal>dow</> except for Sunday. This
6143 matches the <acronym>ISO</> 8601 day of the week numbering.
6144 </para>
6146 </listitem>
6147 </varlistentry>
6149 <varlistentry>
6150 <term><literal>isoyear</literal></term>
6151 <listitem>
6152 <para>
6153 The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals).
6154 </para>
6156 <screen>
6157 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6158 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6159 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6160 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6161 </screen>
6163 <para>
6164 Each <acronym>ISO</acronym> year begins with the Monday of the week containing the 4th of January, so in early January or late December the <acronym>ISO</acronym> year may be different from the Gregorian year. See the <literal>week</literal> field for more information.
6165 </para>
6166 <para>
6167 This field is not available in PostgreSQL releases prior to 8.3.
6168 </para>
6169 </listitem>
6170 </varlistentry>
6172 <varlistentry>
6173 <term><literal>microseconds</literal></term>
6174 <listitem>
6175 <para>
6176 The seconds field, including fractional parts, multiplied by 1
6177 000 000. Note that this includes full seconds.
6178 </para>
6180 <screen>
6181 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6182 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6183 </screen>
6184 </listitem>
6185 </varlistentry>
6187 <varlistentry>
6188 <term><literal>millennium</literal></term>
6189 <listitem>
6190 <para>
6191 The millennium
6192 </para>
6194 <screen>
6195 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6196 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6197 </screen>
6199 <para>
6200 Years in the 1900s are in the second millennium.
6201 The third millennium starts January 1, 2001.
6202 </para>
6204 <para>
6205 <productname>PostgreSQL</productname> releases before 8.0 did not
6206 follow the conventional numbering of millennia, but just returned
6207 the year field divided by 1000.
6208 </para>
6209 </listitem>
6210 </varlistentry>
6212 <varlistentry>
6213 <term><literal>milliseconds</literal></term>
6214 <listitem>
6215 <para>
6216 The seconds field, including fractional parts, multiplied by
6217 1000. Note that this includes full seconds.
6218 </para>
6220 <screen>
6221 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6222 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6223 </screen>
6224 </listitem>
6225 </varlistentry>
6227 <varlistentry>
6228 <term><literal>minute</literal></term>
6229 <listitem>
6230 <para>
6231 The minutes field (0 - 59)
6232 </para>
6234 <screen>
6235 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6236 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6237 </screen>
6238 </listitem>
6239 </varlistentry>
6241 <varlistentry>
6242 <term><literal>month</literal></term>
6243 <listitem>
6244 <para>
6245 For <type>timestamp</type> values, the number of the month
6246 within the year (1 - 12) ; for <type>interval</type> values
6247 the number of months, modulo 12 (0 - 11)
6248 </para>
6250 <screen>
6251 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6252 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6254 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6255 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6257 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6258 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6259 </screen>
6260 </listitem>
6261 </varlistentry>
6263 <varlistentry>
6264 <term><literal>quarter</literal></term>
6265 <listitem>
6266 <para>
6267 The quarter of the year (1 - 4) that the day is in
6268 </para>
6270 <screen>
6271 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6272 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6273 </screen>
6274 </listitem>
6275 </varlistentry>
6277 <varlistentry>
6278 <term><literal>second</literal></term>
6279 <listitem>
6280 <para>
6281 The seconds field, including fractional parts (0 -
6282 59<footnote><simpara>60 if leap seconds are
6283 implemented by the operating system</simpara></footnote>)
6284 </para>
6286 <screen>
6287 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6288 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6290 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6291 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6292 </screen>
6293 </listitem>
6294 </varlistentry>
6295 <varlistentry>
6296 <term><literal>timezone</literal></term>
6297 <listitem>
6298 <para>
6299 The time zone offset from UTC, measured in seconds. Positive values
6300 correspond to time zones east of UTC, negative values to
6301 zones west of UTC.
6302 </para>
6303 </listitem>
6304 </varlistentry>
6306 <varlistentry>
6307 <term><literal>timezone_hour</literal></term>
6308 <listitem>
6309 <para>
6310 The hour component of the time zone offset
6311 </para>
6312 </listitem>
6313 </varlistentry>
6315 <varlistentry>
6316 <term><literal>timezone_minute</literal></term>
6317 <listitem>
6318 <para>
6319 The minute component of the time zone offset
6320 </para>
6321 </listitem>
6322 </varlistentry>
6324 <varlistentry>
6325 <term><literal>week</literal></term>
6326 <listitem>
6327 <para>
6328 The number of the week of the year that the day is in. By definition
6329 (<acronym>ISO</acronym> 8601), the first week of a year
6330 contains January 4 of that year. (The <acronym>ISO</acronym>-8601
6331 week starts on Monday.) In other words, the first Thursday of
6332 a year is in week 1 of that year.
6333 </para>
6334 <para>
6335 Because of this, it is possible for early January dates to be part of the
6336 52nd or 53rd week of the previous year. For example, <literal>2005-01-01</>
6337 is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of
6338 the 52nd week of year 2005.
6339 </para>
6341 <screen>
6342 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6343 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6344 </screen>
6345 </listitem>
6346 </varlistentry>
6348 <varlistentry>
6349 <term><literal>year</literal></term>
6350 <listitem>
6351 <para>
6352 The year field. Keep in mind there is no <literal>0 AD</>, so subtracting
6353 <literal>BC</> years from <literal>AD</> years should be done with care.
6354 </para>
6356 <screen>
6357 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6358 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6359 </screen>
6360 </listitem>
6361 </varlistentry>
6363 </variablelist>
6364 </para>
6366 <para>
6367 The <function>extract</function> function is primarily intended
6368 for computational processing. For formatting date/time values for
6369 display, see <xref linkend="functions-formatting">.
6370 </para>
6372 <para>
6373 The <function>date_part</function> function is modeled on the traditional
6374 <productname>Ingres</productname> equivalent to the
6375 <acronym>SQL</acronym>-standard function <function>extract</function>:
6376 <synopsis>
6377 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6378 </synopsis>
6379 Note that here the <replaceable>field</replaceable> parameter needs to
6380 be a string value, not a name. The valid field names for
6381 <function>date_part</function> are the same as for
6382 <function>extract</function>.
6383 </para>
6385 <screen>
6386 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
6387 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6389 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
6390 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
6391 </screen>
6393 </sect2>
6395 <sect2 id="functions-datetime-trunc">
6396 <title><function>date_trunc</function></title>
6398 <indexterm>
6399 <primary>date_trunc</primary>
6400 </indexterm>
6402 <para>
6403 The function <function>date_trunc</function> is conceptually
6404 similar to the <function>trunc</function> function for numbers.
6405 </para>
6407 <para>
6408 <synopsis>
6409 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6410 </synopsis>
6411 <replaceable>source</replaceable> is a value expression of type
6412 <type>timestamp</type> or <type>interval</>.
6413 (Values of type <type>date</type> and
6414 <type>time</type> are cast automatically, to <type>timestamp</type> or
6415 <type>interval</> respectively.)
6416 <replaceable>field</replaceable> selects to which precision to
6417 truncate the input value. The return value is of type
6418 <type>timestamp</type> or <type>interval</>
6419 with all fields that are less significant than the
6420 selected one set to zero (or one, for day and month).
6421 </para>
6423 <para>
6424 Valid values for <replaceable>field</replaceable> are:
6425 <simplelist>
6426 <member><literal>microseconds</literal></member>
6427 <member><literal>milliseconds</literal></member>
6428 <member><literal>second</literal></member>
6429 <member><literal>minute</literal></member>
6430 <member><literal>hour</literal></member>
6431 <member><literal>day</literal></member>
6432 <member><literal>week</literal></member>
6433 <member><literal>month</literal></member>
6434 <member><literal>quarter</literal></member>
6435 <member><literal>year</literal></member>
6436 <member><literal>decade</literal></member>
6437 <member><literal>century</literal></member>
6438 <member><literal>millennium</literal></member>
6439 </simplelist>
6440 </para>
6442 <para>
6443 Examples:
6444 <screen>
6445 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
6446 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
6448 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
6449 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
6450 </screen>
6451 </para>
6452 </sect2>
6454 <sect2 id="functions-datetime-zoneconvert">
6455 <title><literal>AT TIME ZONE</literal></title>
6457 <indexterm>
6458 <primary>time zone</primary>
6459 <secondary>conversion</secondary>
6460 </indexterm>
6462 <indexterm>
6463 <primary>AT TIME ZONE</primary>
6464 </indexterm>
6466 <para>
6467 The <literal>AT TIME ZONE</literal> construct allows conversions
6468 of time stamps to different time zones. <xref
6469 linkend="functions-datetime-zoneconvert-table"> shows its
6470 variants.
6471 </para>
6473 <table id="functions-datetime-zoneconvert-table">
6474 <title><literal>AT TIME ZONE</literal> Variants</title>
6475 <tgroup cols="3">
6476 <thead>
6477 <row>
6478 <entry>Expression</entry>
6479 <entry>Return Type</entry>
6480 <entry>Description</entry>
6481 </row>
6482 </thead>
6484 <tbody>
6485 <row>
6486 <entry>
6487 <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6488 </entry>
6489 <entry><type>timestamp with time zone</type></entry>
6490 <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
6491 </row>
6493 <row>
6494 <entry>
6495 <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6496 </entry>
6497 <entry><type>timestamp without time zone</type></entry>
6498 <entry>Convert given time stamp <emphasis>with time zone</> to the new time zone</entry>
6499 </row>
6501 <row>
6502 <entry>
6503 <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6504 </entry>
6505 <entry><type>time with time zone</type></entry>
6506 <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
6507 </row>
6508 </tbody>
6509 </tgroup>
6510 </table>
6512 <para>
6513 In these expressions, the desired time zone <replaceable>zone</> can be
6514 specified either as a text string (e.g., <literal>'PST'</literal>)
6515 or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
6516 In the text case, a time zone name can be specified in any of the ways
6517 described in <xref linkend="datatype-timezones">.
6518 </para>
6520 <para>
6521 Examples (supposing that the local time zone is <literal>PST8PDT</>):
6522 <screen>
6523 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
6524 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
6526 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
6527 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
6528 </screen>
6529 The first example takes a time stamp without time zone and interprets it as MST time
6530 (UTC-7), which is then converted to PST (UTC-8) for display. The second example takes
6531 a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
6532 </para>
6534 <para>
6535 The function <literal><function>timezone</function>(<replaceable>zone</>,
6536 <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
6537 <literal><replaceable>timestamp</> AT TIME ZONE
6538 <replaceable>zone</></literal>.
6539 </para>
6540 </sect2>
6542 <sect2 id="functions-datetime-current">
6543 <title>Current Date/Time</title>
6545 <indexterm>
6546 <primary>date</primary>
6547 <secondary>current</secondary>
6548 </indexterm>
6550 <indexterm>
6551 <primary>time</primary>
6552 <secondary>current</secondary>
6553 </indexterm>
6555 <para>
6556 <productname>PostgreSQL</productname> provides a number of functions
6557 that return values related to the current date and time. These
6558 SQL-standard functions all return values based on the start time of
6559 the current transaction:
6560 <synopsis>
6561 CURRENT_DATE
6562 CURRENT_TIME
6563 CURRENT_TIMESTAMP
6564 CURRENT_TIME(<replaceable>precision</replaceable>)
6565 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
6566 LOCALTIME
6567 LOCALTIMESTAMP
6568 LOCALTIME(<replaceable>precision</replaceable>)
6569 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
6570 </synopsis>
6571 </para>
6573 <para>
6574 <function>CURRENT_TIME</function> and
6575 <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
6576 <function>LOCALTIME</function> and
6577 <function>LOCALTIMESTAMP</function> deliver values without time zone.
6578 </para>
6580 <para>
6581 <function>CURRENT_TIME</function>,
6582 <function>CURRENT_TIMESTAMP</function>,
6583 <function>LOCALTIME</function>, and
6584 <function>LOCALTIMESTAMP</function>
6585 can optionally be given
6586 a precision parameter, which causes the result to be rounded
6587 to that many fractional digits in the seconds field. Without a precision parameter,
6588 the result is given to the full available precision.
6589 </para>
6591 <para>
6592 Some examples:
6593 <screen>
6594 SELECT CURRENT_TIME;
6595 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
6597 SELECT CURRENT_DATE;
6598 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
6600 SELECT CURRENT_TIMESTAMP;
6601 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
6603 SELECT CURRENT_TIMESTAMP(2);
6604 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
6606 SELECT LOCALTIMESTAMP;
6607 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
6608 </screen>
6609 </para>
6611 <para>
6612 Since these functions return
6613 the start time of the current transaction, their values do not
6614 change during the transaction. This is considered a feature:
6615 the intent is to allow a single transaction to have a consistent
6616 notion of the <quote>current</quote> time, so that multiple
6617 modifications within the same transaction bear the same
6618 time stamp.
6619 </para>
6621 <note>
6622 <para>
6623 Other database systems might advance these values more
6624 frequently.
6625 </para>
6626 </note>
6628 <para>
6629 <productname>PostgreSQL</productname> also provides functions that
6630 return the start time of the current statement, as well as the actual
6631 current time at the instant the function is called. The complete list
6632 of non-SQL-standard time functions is:
6633 <synopsis>
6634 now()
6635 transaction_timestamp()
6636 statement_timestamp()
6637 clock_timestamp()
6638 timeofday()
6639 </synopsis>
6640 </para>
6642 <para>
6643 <function>now()</> is a traditional <productname>PostgreSQL</productname>
6644 equivalent to <function>CURRENT_TIMESTAMP</function>.
6645 <function>transaction_timestamp()</> is likewise equivalent to
6646 <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
6647 what it returns.
6648 <function>statement_timestamp()</> returns the start time of the current
6649 statement (more specifically, the time of receipt of the latest command
6650 message from the client).
6651 <function>statement_timestamp()</> and <function>transaction_timestamp()</>
6652 return the same value during the first command of a transaction, but might
6653 differ during subsequent commands.
6654 <function>clock_timestamp()</> returns the actual current time, and
6655 therefore its value changes even within a single SQL command.
6656 <function>timeofday()</> is a historical
6657 <productname>PostgreSQL</productname> function. Like
6658 <function>clock_timestamp()</>, it returns the actual current time,
6659 but as a formatted <type>text</> string rather than a <type>timestamp
6660 with time zone</> value.
6661 </para>
6663 <para>
6664 All the date/time data types also accept the special literal value
6665 <literal>now</literal> to specify the current date and time (again,
6666 interpreted as the transaction start time). Thus,
6667 the following three all return the same result:
6668 <programlisting>
6669 SELECT CURRENT_TIMESTAMP;
6670 SELECT now();
6671 SELECT TIMESTAMP 'now'; -- incorrect for use with DEFAULT
6672 </programlisting>
6673 </para>
6675 <tip>
6676 <para>
6677 You do not want to use the third form when specifying a <literal>DEFAULT</>
6678 clause while creating a table. The system will convert <literal>now</literal>
6679 to a <type>timestamp</type> as soon as the constant is parsed, so that when
6680 the default value is needed,
6681 the time of the table creation would be used! The first two
6682 forms will not be evaluated until the default value is used,
6683 because they are function calls. Thus they will give the desired
6684 behavior of defaulting to the time of row insertion.
6685 </para>
6686 </tip>
6687 </sect2>
6689 <sect2 id="functions-datetime-delay">
6690 <title>Delaying Execution</title>
6692 <indexterm>
6693 <primary>pg_sleep</primary>
6694 </indexterm>
6695 <indexterm>
6696 <primary>sleep</primary>
6697 </indexterm>
6698 <indexterm>
6699 <primary>delay</primary>
6700 </indexterm>
6702 <para>
6703 The following function is available to delay execution of the server
6704 process:
6705 <synopsis>
6706 pg_sleep(<replaceable>seconds</replaceable>)
6707 </synopsis>
6709 <function>pg_sleep</function> makes the current session's process
6710 sleep until <replaceable>seconds</replaceable> seconds have
6711 elapsed. <replaceable>seconds</replaceable> is a value of type
6712 <type>double precision</>, so fractional-second delays can be specified.
6713 For example:
6715 <programlisting>
6716 SELECT pg_sleep(1.5);
6717 </programlisting>
6718 </para>
6720 <note>
6721 <para>
6722 The effective resolution of the sleep interval is platform-specific;
6723 0.01 seconds is a common value. The sleep delay will be at least as long
6724 as specified. It might be longer depending on factors such as server load.
6725 </para>
6726 </note>
6728 <warning>
6729 <para>
6730 Make sure that your session does not hold more locks than necessary
6731 when calling <function>pg_sleep</function>. Otherwise other sessions
6732 might have to wait for your sleeping process, slowing down the entire
6733 system.
6734 </para>
6735 </warning>
6736 </sect2>
6738 </sect1>
6741 <sect1 id="functions-enum">
6742 <title>Enum Support Functions</title>
6744 <para>
6745 For enum types (described in <xref linkend="datatype-enum">),
6746 there are several functions that allow cleaner programming without
6747 hard-coding particular values of an enum type.
6748 These are listed in <xref linkend="functions-enum-table">. The examples
6749 assume an enum type created as:
6751 <programlisting>
6752 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
6753 </programlisting>
6755 </para>
6757 <table id="functions-enum-table">
6758 <title>Enum Support Functions</title>
6759 <tgroup cols="4">
6760 <thead>
6761 <row>
6762 <entry>Function</entry>
6763 <entry>Description</entry>
6764 <entry>Example</entry>
6765 <entry>Example Result</entry>
6766 </row>
6767 </thead>
6768 <tbody>
6769 <row>
6770 <entry><literal>enum_first(anyenum)</literal></entry>
6771 <entry>Returns the first value of the input enum type</entry>
6772 <entry><literal>enum_first(null::rainbow)</literal></entry>
6773 <entry><literal>red</literal></entry>
6774 </row>
6775 <row>
6776 <entry><literal>enum_last(anyenum)</literal></entry>
6777 <entry>Returns the last value of the input enum type</entry>
6778 <entry><literal>enum_last(null::rainbow)</literal></entry>
6779 <entry><literal>purple</literal></entry>
6780 </row>
6781 <row>
6782 <entry><literal>enum_range(anyenum)</literal></entry>
6783 <entry>Returns all values of the input enum type in an ordered array</entry>
6784 <entry><literal>enum_range(null::rainbow)</literal></entry>
6785 <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
6786 </row>
6787 <row>
6788 <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
6789 <entry morerows="2">
6790 Returns the range between the two given enum values, as an ordered
6791 array. The values must be from the same enum type. If the first
6792 parameter is null, the result will start with the first value of
6793 the enum type.
6794 If the second parameter is null, the result will end with the last
6795 value of the enum type.
6796 </entry>
6797 <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
6798 <entry><literal>{orange,yellow,green}</literal></entry>
6799 </row>
6800 <row>
6801 <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
6802 <entry><literal>{red,orange,yellow,green}</literal></entry>
6803 </row>
6804 <row>
6805 <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
6806 <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
6807 </row>
6808 </tbody>
6809 </tgroup>
6810 </table>
6812 <para>
6813 Notice that except for the two-argument form of <function>enum_range</>,
6814 these functions disregard the specific value passed to them; they care
6815 only about its declared datatype. Either NULL or a specific value of
6816 the type can be passed, with the same result. It is more common to
6817 apply these functions to a table column or function argument than to
6818 a hardwired type name as suggested by the examples.
6819 </para>
6820 </sect1>
6822 <sect1 id="functions-geometry">
6823 <title>Geometric Functions and Operators</title>
6825 <para>
6826 The geometric types <type>point</type>, <type>box</type>,
6827 <type>lseg</type>, <type>line</type>, <type>path</type>,
6828 <type>polygon</type>, and <type>circle</type> have a large set of
6829 native support functions and operators, shown in <xref
6830 linkend="functions-geometry-op-table">, <xref
6831 linkend="functions-geometry-func-table">, and <xref
6832 linkend="functions-geometry-conv-table">.
6833 </para>
6835 <caution>
6836 <para>
6837 Note that the <quote>same as</> operator, <literal>~=</>, represents
6838 the usual notion of equality for the <type>point</type>,
6839 <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
6840 Some of these types also have an <literal>=</> operator, but
6841 <literal>=</> compares
6842 for equal <emphasis>areas</> only. The other scalar comparison operators
6843 (<literal>&lt;=</> and so on) likewise compare areas for these types.
6844 </para>
6845 </caution>
6847 <table id="functions-geometry-op-table">
6848 <title>Geometric Operators</title>
6849 <tgroup cols="3">
6850 <thead>
6851 <row>
6852 <entry>Operator</entry>
6853 <entry>Description</entry>
6854 <entry>Example</entry>
6855 </row>
6856 </thead>
6857 <tbody>
6858 <row>
6859 <entry> <literal>+</literal> </entry>
6860 <entry>Translation</entry>
6861 <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
6862 </row>
6863 <row>
6864 <entry> <literal>-</literal> </entry>
6865 <entry>Translation</entry>
6866 <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
6867 </row>
6868 <row>
6869 <entry> <literal>*</literal> </entry>
6870 <entry>Scaling/rotation</entry>
6871 <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
6872 </row>
6873 <row>
6874 <entry> <literal>/</literal> </entry>
6875 <entry>Scaling/rotation</entry>
6876 <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
6877 </row>
6878 <row>
6879 <entry> <literal>#</literal> </entry>
6880 <entry>Point or box of intersection</entry>
6881 <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
6882 </row>
6883 <row>
6884 <entry> <literal>#</literal> </entry>
6885 <entry>Number of points in path or polygon</entry>
6886 <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
6887 </row>
6888 <row>
6889 <entry> <literal>@-@</literal> </entry>
6890 <entry>Length or circumference</entry>
6891 <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
6892 </row>
6893 <row>
6894 <entry> <literal>@@</literal> </entry>
6895 <entry>Center</entry>
6896 <entry><literal>@@ circle '((0,0),10)'</literal></entry>
6897 </row>
6898 <row>
6899 <entry> <literal>##</literal> </entry>
6900 <entry>Closest point to first operand on second operand</entry>
6901 <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
6902 </row>
6903 <row>
6904 <entry> <literal>&lt;-&gt;</literal> </entry>
6905 <entry>Distance between</entry>
6906 <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
6907 </row>
6908 <row>
6909 <entry> <literal>&amp;&amp;</literal> </entry>
6910 <entry>Overlaps?</entry>
6911 <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
6912 </row>
6913 <row>
6914 <entry> <literal>&lt;&lt;</literal> </entry>
6915 <entry>Is strictly left of?</entry>
6916 <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
6917 </row>
6918 <row>
6919 <entry> <literal>&gt;&gt;</literal> </entry>
6920 <entry>Is strictly right of?</entry>
6921 <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
6922 </row>
6923 <row>
6924 <entry> <literal>&amp;&lt;</literal> </entry>
6925 <entry>Does not extend to the right of?</entry>
6926 <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
6927 </row>
6928 <row>
6929 <entry> <literal>&amp;&gt;</literal> </entry>
6930 <entry>Does not extend to the left of?</entry>
6931 <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
6932 </row>
6933 <row>
6934 <entry> <literal>&lt;&lt;|</literal> </entry>
6935 <entry>Is strictly below?</entry>
6936 <entry><literal>box '((0,0),(3,3))' &lt;&lt;| box '((3,4),(5,5))'</literal></entry>
6937 </row>
6938 <row>
6939 <entry> <literal>|&gt;&gt;</literal> </entry>
6940 <entry>Is strictly above?</entry>
6941 <entry><literal>box '((3,4),(5,5))' |&gt;&gt; box '((0,0),(3,3))'</literal></entry>
6942 </row>
6943 <row>
6944 <entry> <literal>&amp;&lt;|</literal> </entry>
6945 <entry>Does not extend above?</entry>
6946 <entry><literal>box '((0,0),(1,1))' &amp;&lt;| box '((0,0),(2,2))'</literal></entry>
6947 </row>
6948 <row>
6949 <entry> <literal>|&amp;&gt;</literal> </entry>
6950 <entry>Does not extend below?</entry>
6951 <entry><literal>box '((0,0),(3,3))' |&amp;&gt; box '((0,0),(2,2))'</literal></entry>
6952 </row>
6953 <row>
6954 <entry> <literal>&lt;^</literal> </entry>
6955 <entry>Is below (allows touching)?</entry>
6956 <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
6957 </row>
6958 <row>
6959 <entry> <literal>&gt;^</literal> </entry>
6960 <entry>Is above (allows touching)?</entry>
6961 <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
6962 </row>
6963 <row>
6964 <entry> <literal>?#</literal> </entry>
6965 <entry>Intersects?</entry>
6966 <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
6967 </row>
6968 <row>
6969 <entry> <literal>?-</literal> </entry>
6970 <entry>Is horizontal?</entry>
6971 <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
6972 </row>
6973 <row>
6974 <entry> <literal>?-</literal> </entry>
6975 <entry>Are horizontally aligned?</entry>
6976 <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
6977 </row>
6978 <row>
6979 <entry> <literal>?|</literal> </entry>
6980 <entry>Is vertical?</entry>
6981 <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
6982 </row>
6983 <row>
6984 <entry> <literal>?|</literal> </entry>
6985 <entry>Are vertically aligned?</entry>
6986 <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
6987 </row>
6988 <row>
6989 <entry> <literal>?-|</literal> </entry>
6990 <entry>Is perpendicular?</entry>
6991 <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
6992 </row>
6993 <row>
6994 <entry> <literal>?||</literal> </entry>
6995 <entry>Are parallel?</entry>
6996 <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
6997 </row>
6998 <row>
6999 <entry> <literal>@&gt;</literal> </entry>
7000 <entry>Contains?</entry>
7001 <entry><literal>circle '((0,0),2)' @&gt; point '(1,1)'</literal></entry>
7002 </row>
7003 <row>
7004 <entry> <literal>&lt;@</literal> </entry>
7005 <entry>Contained in or on?</entry>
7006 <entry><literal>point '(1,1)' &lt;@ circle '((0,0),2)'</literal></entry>
7007 </row>
7008 <row>
7009 <entry> <literal>~=</literal> </entry>
7010 <entry>Same as?</entry>
7011 <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7012 </row>
7013 </tbody>
7014 </tgroup>
7015 </table>
7017 <note>
7018 <para>
7019 Before <productname>PostgreSQL</productname> 8.2, the containment
7020 operators <literal>@&gt;</> and <literal>&lt;@</> were respectively
7021 called <literal>~</> and <literal>@</>. These names are still
7022 available, but are deprecated and will eventually be retired.
7023 </para>
7024 </note>
7026 <indexterm>
7027 <primary>area</primary>
7028 </indexterm>
7029 <indexterm>
7030 <primary>center</primary>
7031 </indexterm>
7032 <indexterm>
7033 <primary>diameter</primary>
7034 </indexterm>
7035 <indexterm>
7036 <primary>height</primary>
7037 </indexterm>
7038 <indexterm>
7039 <primary>isclosed</primary>
7040 </indexterm>
7041 <indexterm>
7042 <primary>isopen</primary>
7043 </indexterm>
7044 <indexterm>
7045 <primary>length</primary>
7046 </indexterm>
7047 <indexterm>
7048 <primary>npoints</primary>
7049 </indexterm>
7050 <indexterm>
7051 <primary>pclose</primary>
7052 </indexterm>
7053 <indexterm>
7054 <primary>popen</primary>
7055 </indexterm>
7056 <indexterm>
7057 <primary>radius</primary>
7058 </indexterm>
7059 <indexterm>
7060 <primary>width</primary>
7061 </indexterm>
7063 <table id="functions-geometry-func-table">
7064 <title>Geometric Functions</title>
7065 <tgroup cols="4">
7066 <thead>
7067 <row>
7068 <entry>Function</entry>
7069 <entry>Return Type</entry>
7070 <entry>Description</entry>
7071 <entry>Example</entry>
7072 </row>
7073 </thead>
7074 <tbody>
7075 <row>
7076 <entry><literal><function>area</function>(<replaceable>object</>)</literal></entry>
7077 <entry><type>double precision</type></entry>
7078 <entry>area</entry>
7079 <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7080 </row>
7081 <row>
7082 <entry><literal><function>center</function>(<replaceable>object</>)</literal></entry>
7083 <entry><type>point</type></entry>
7084 <entry>center</entry>
7085 <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7086 </row>
7087 <row>
7088 <entry><literal><function>diameter</function>(<type>circle</>)</literal></entry>
7089 <entry><type>double precision</type></entry>
7090 <entry>diameter of circle</entry>
7091 <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7092 </row>
7093 <row>
7094 <entry><literal><function>height</function>(<type>box</>)</literal></entry>
7095 <entry><type>double precision</type></entry>
7096 <entry>vertical size of box</entry>
7097 <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7098 </row>
7099 <row>
7100 <entry><literal><function>isclosed</function>(<type>path</>)</literal></entry>
7101 <entry><type>boolean</type></entry>
7102 <entry>a closed path?</entry>
7103 <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7104 </row>
7105 <row>
7106 <entry><literal><function>isopen</function>(<type>path</>)</literal></entry>
7107 <entry><type>boolean</type></entry>
7108 <entry>an open path?</entry>
7109 <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7110 </row>
7111 <row>
7112 <entry><literal><function>length</function>(<replaceable>object</>)</literal></entry>
7113 <entry><type>double precision</type></entry>
7114 <entry>length</entry>
7115 <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7116 </row>
7117 <row>
7118 <entry><literal><function>npoints</function>(<type>path</>)</literal></entry>
7119 <entry><type>int</type></entry>
7120 <entry>number of points</entry>
7121 <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7122 </row>
7123 <row>
7124 <entry><literal><function>npoints</function>(<type>polygon</>)</literal></entry>
7125 <entry><type>int</type></entry>
7126 <entry>number of points</entry>
7127 <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7128 </row>
7129 <row>
7130 <entry><literal><function>pclose</function>(<type>path</>)</literal></entry>
7131 <entry><type>path</type></entry>
7132 <entry>convert path to closed</entry>
7133 <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7134 </row>
7135 <![IGNORE[
7136 <!-- Not defined by this name. Implements the intersection operator '#' -->
7137 <row>
7138 <entry><literal><function>point</function>(<type>lseg</>, <type>lseg</>)</literal></entry>
7139 <entry><type>point</type></entry>
7140 <entry>intersection</entry>
7141 <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7142 </row>
7144 <row>
7145 <entry><literal><function>popen</function>(<type>path</>)</literal></entry>
7146 <entry><type>path</type></entry>
7147 <entry>convert path to open</entry>
7148 <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7149 </row>
7150 <row>
7151 <entry><literal><function>radius</function>(<type>circle</type>)</literal></entry>
7152 <entry><type>double precision</type></entry>
7153 <entry>radius of circle</entry>
7154 <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7155 </row>
7156 <row>
7157 <entry><literal><function>width</function>(<type>box</>)</literal></entry>
7158 <entry><type>double precision</type></entry>
7159 <entry>horizontal size of box</entry>
7160 <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7161 </row>
7162 </tbody>
7163 </tgroup>
7164 </table>
7166 <table id="functions-geometry-conv-table">
7167 <title>Geometric Type Conversion Functions</title>
7168 <tgroup cols="4">
7169 <thead>
7170 <row>
7171 <entry>Function</entry>
7172 <entry>Return Type</entry>
7173 <entry>Description</entry>
7174 <entry>Example</entry>
7175 </row>
7176 </thead>
7177 <tbody>
7178 <row>
7179 <entry><literal><function>box</function>(<type>circle</type>)</literal></entry>
7180 <entry><type>box</type></entry>
7181 <entry>circle to box</entry>
7182 <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7183 </row>
7184 <row>
7185 <entry><literal><function>box</function>(<type>point</type>, <type>point</type>)</literal></entry>
7186 <entry><type>box</type></entry>
7187 <entry>points to box</entry>
7188 <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7189 </row>
7190 <row>
7191 <entry><literal><function>box</function>(<type>polygon</type>)</literal></entry>
7192 <entry><type>box</type></entry>
7193 <entry>polygon to box</entry>
7194 <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7195 </row>
7196 <row>
7197 <entry><literal><function>circle</function>(<type>box</type>)</literal></entry>
7198 <entry><type>circle</type></entry>
7199 <entry>box to circle</entry>
7200 <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7201 </row>
7202 <row>
7203 <entry><literal><function>circle</function>(<type>point</type>, <type>double precision</type>)</literal></entry>
7204 <entry><type>circle</type></entry>
7205 <entry>center and radius to circle</entry>
7206 <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7207 </row>
7208 <row>
7209 <entry><literal><function>circle</function>(<type>polygon</type>)</literal></entry>
7210 <entry><type>circle</type></entry>
7211 <entry>polygon to circle</entry>
7212 <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7213 </row>
7214 <row>
7215 <entry><literal><function>lseg</function>(<type>box</type>)</literal></entry>
7216 <entry><type>lseg</type></entry>
7217 <entry>box diagonal to line segment</entry>
7218 <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7219 </row>
7220 <row>
7221 <entry><literal><function>lseg</function>(<type>point</type>, <type>point</type>)</literal></entry>
7222 <entry><type>lseg</type></entry>
7223 <entry>points to line segment</entry>
7224 <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7225 </row>
7226 <row>
7227 <entry><literal><function>path</function>(<type>polygon</type>)</literal></entry>
7228 <entry><type>point</type></entry>
7229 <entry>polygon to path</entry>
7230 <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7231 </row>
7232 <row>
7233 <entry><literal><function>point</function>(<type>double
7234 precision</type>, <type>double precision</type>)</literal></entry>
7235 <entry><type>point</type></entry>
7236 <entry>construct point</entry>
7237 <entry><literal>point(23.4, -44.5)</literal></entry>
7238 </row>
7239 <row>
7240 <entry><literal><function>point</function>(<type>box</type>)</literal></entry>
7241 <entry><type>point</type></entry>
7242 <entry>center of box</entry>
7243 <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7244 </row>
7245 <row>
7246 <entry><literal><function>point</function>(<type>circle</type>)</literal></entry>
7247 <entry><type>point</type></entry>
7248 <entry>center of circle</entry>
7249 <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7250 </row>
7251 <row>
7252 <entry><literal><function>point</function>(<type>lseg</type>)</literal></entry>
7253 <entry><type>point</type></entry>
7254 <entry>center of line segment</entry>
7255 <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7256 </row>
7257 <row>
7258 <entry><literal><function>point</function>(<type>polygon</type>)</literal></entry>
7259 <entry><type>point</type></entry>
7260 <entry>center of polygon</entry>
7261 <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7262 </row>
7263 <row>
7264 <entry><literal><function>polygon</function>(<type>box</type>)</literal></entry>
7265 <entry><type>polygon</type></entry>
7266 <entry>box to 4-point polygon</entry>
7267 <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7268 </row>
7269 <row>
7270 <entry><literal><function>polygon</function>(<type>circle</type>)</literal></entry>
7271 <entry><type>polygon</type></entry>
7272 <entry>circle to 12-point polygon</entry>
7273 <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7274 </row>
7275 <row>
7276 <entry><literal><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</literal></entry>
7277 <entry><type>polygon</type></entry>
7278 <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
7279 <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7280 </row>
7281 <row>
7282 <entry><literal><function>polygon</function>(<type>path</type>)</literal></entry>
7283 <entry><type>polygon</type></entry>
7284 <entry>path to polygon</entry>
7285 <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7286 </row>
7287 </tbody>
7288 </tgroup>
7289 </table>
7291 <para>
7292 It is possible to access the two component numbers of a <type>point</>
7293 as though it were an array with indices 0 and 1. For example, if
7294 <literal>t.p</> is a <type>point</> column then
7295 <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7296 <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7297 In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7298 as an array of two <type>point</> values.
7299 </para>
7301 <para>
7302 The <function>area</function> function works for the types
7303 <type>box</type>, <type>circle</type>, and <type>path</type>.
7304 The <function>area</function> function only works on the
7305 <type>path</type> data type if the points in the
7306 <type>path</type> are non-intersecting. For example, the
7307 <type>path</type>
7308 <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7309 won't work, however, the following visually identical
7310 <type>path</type>
7311 <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7312 will work. If the concept of an intersecting versus
7313 non-intersecting <type>path</type> is confusing, draw both of the
7314 above <type>path</type>s side by side on a piece of graph paper.
7315 </para>
7317 </sect1>
7320 <sect1 id="functions-net">
7321 <title>Network Address Functions and Operators</title>
7323 <para>
7324 <xref linkend="cidr-inet-operators-table"> shows the operators
7325 available for the <type>cidr</type> and <type>inet</type> types.
7326 The operators <literal>&lt;&lt;</literal>,
7327 <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
7328 <literal>&gt;&gt;=</literal> test for subnet inclusion. They
7329 consider only the network parts of the two addresses, ignoring any
7330 host part, and determine whether one network part is identical to
7331 or a subnet of the other.
7332 </para>
7334 <table id="cidr-inet-operators-table">
7335 <title><type>cidr</type> and <type>inet</type> Operators</title>
7336 <tgroup cols="3">
7337 <thead>
7338 <row>
7339 <entry>Operator</entry>
7340 <entry>Description</entry>
7341 <entry>Example</entry>
7342 </row>
7343 </thead>
7344 <tbody>
7345 <row>
7346 <entry> <literal>&lt;</literal> </entry>
7347 <entry>is less than</entry>
7348 <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
7349 </row>
7350 <row>
7351 <entry> <literal>&lt;=</literal> </entry>
7352 <entry>is less than or equal</entry>
7353 <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
7354 </row>
7355 <row>
7356 <entry> <literal>=</literal> </entry>
7357 <entry>equals</entry>
7358 <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
7359 </row>
7360 <row>
7361 <entry> <literal>&gt;=</literal> </entry>
7362 <entry>is greater or equal</entry>
7363 <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
7364 </row>
7365 <row>
7366 <entry> <literal>&gt;</literal> </entry>
7367 <entry>is greater than</entry>
7368 <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
7369 </row>
7370 <row>
7371 <entry> <literal>&lt;&gt;</literal> </entry>
7372 <entry>is not equal</entry>
7373 <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
7374 </row>
7375 <row>
7376 <entry> <literal>&lt;&lt;</literal> </entry>
7377 <entry>is contained within</entry>
7378 <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
7379 </row>
7380 <row>
7381 <entry> <literal>&lt;&lt;=</literal> </entry>
7382 <entry>is contained within or equals</entry>
7383 <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
7384 </row>
7385 <row>
7386 <entry> <literal>&gt;&gt;</literal> </entry>
7387 <entry>contains</entry>
7388 <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
7389 </row>
7390 <row>
7391 <entry> <literal>&gt;&gt;=</literal> </entry>
7392 <entry>contains or equals</entry>
7393 <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
7394 </row>
7395 <row>
7396 <entry> <literal>~</literal> </entry>
7397 <entry>bitwise NOT</entry>
7398 <entry><literal>~ inet '192.168.1.6'</literal></entry>
7399 </row>
7400 <row>
7401 <entry> <literal>&amp;</literal> </entry>
7402 <entry>bitwise AND</entry>
7403 <entry><literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal></entry>
7404 </row>
7405 <row>
7406 <entry> <literal>|</literal> </entry>
7407 <entry>bitwise OR</entry>
7408 <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
7409 </row>
7410 <row>
7411 <entry> <literal>+</literal> </entry>
7412 <entry>addition</entry>
7413 <entry><literal>inet '192.168.1.6' + 25</literal></entry>
7414 </row>
7415 <row>
7416 <entry> <literal>-</literal> </entry>
7417 <entry>subtraction</entry>
7418 <entry><literal>inet '192.168.1.43' - 36</literal></entry>
7419 </row>
7420 <row>
7421 <entry> <literal>-</literal> </entry>
7422 <entry>subtraction</entry>
7423 <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
7424 </row>
7425 </tbody>
7426 </tgroup>
7427 </table>
7429 <para>
7430 <xref linkend="cidr-inet-functions-table"> shows the functions
7431 available for use with the <type>cidr</type> and <type>inet</type>
7432 types. The <function>host</function>,
7433 <function>text</function>, and <function>abbrev</function>
7434 functions are primarily intended to offer alternative display
7435 formats.
7436 </para>
7438 <table id="cidr-inet-functions-table">
7439 <title><type>cidr</type> and <type>inet</type> Functions</title>
7440 <tgroup cols="5">
7441 <thead>
7442 <row>
7443 <entry>Function</entry>
7444 <entry>Return Type</entry>
7445 <entry>Description</entry>
7446 <entry>Example</entry>
7447 <entry>Result</entry>
7448 </row>
7449 </thead>
7450 <tbody>
7451 <row>
7452 <entry><literal><function>abbrev</function>(<type>inet</type>)</literal></entry>
7453 <entry><type>text</type></entry>
7454 <entry>abbreviated display format as text</entry>
7455 <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
7456 <entry><literal>10.1.0.0/16</literal></entry>
7457 </row>
7458 <row>
7459 <entry><literal><function>abbrev</function>(<type>cidr</type>)</literal></entry>
7460 <entry><type>text</type></entry>
7461 <entry>abbreviated display format as text</entry>
7462 <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
7463 <entry><literal>10.1/16</literal></entry>
7464 </row>
7465 <row>
7466 <entry><literal><function>broadcast</function>(<type>inet</type>)</literal></entry>
7467 <entry><type>inet</type></entry>
7468 <entry>broadcast address for network</entry>
7469 <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
7470 <entry><literal>192.168.1.255/24</literal></entry>
7471 </row>
7472 <row>
7473 <entry><literal><function>family</function>(<type>inet</type>)</literal></entry>
7474 <entry><type>int</type></entry>
7475 <entry>extract family of address; <literal>4</literal> for IPv4,
7476 <literal>6</literal> for IPv6</entry>
7477 <entry><literal>family('::1')</literal></entry>
7478 <entry><literal>6</literal></entry>
7479 </row>
7480 <row>
7481 <entry><literal><function>host</function>(<type>inet</type>)</literal></entry>
7482 <entry><type>text</type></entry>
7483 <entry>extract IP address as text</entry>
7484 <entry><literal>host('192.168.1.5/24')</literal></entry>
7485 <entry><literal>192.168.1.5</literal></entry>
7486 </row>
7487 <row>
7488 <entry><literal><function>hostmask</function>(<type>inet</type>)</literal></entry>
7489 <entry><type>inet</type></entry>
7490 <entry>construct host mask for network</entry>
7491 <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
7492 <entry><literal>0.0.0.3</literal></entry>
7493 </row>
7494 <row>
7495 <entry><literal><function>masklen</function>(<type>inet</type>)</literal></entry>
7496 <entry><type>int</type></entry>
7497 <entry>extract netmask length</entry>
7498 <entry><literal>masklen('192.168.1.5/24')</literal></entry>
7499 <entry><literal>24</literal></entry>
7500 </row>
7501 <row>
7502 <entry><literal><function>netmask</function>(<type>inet</type>)</literal></entry>
7503 <entry><type>inet</type></entry>
7504 <entry>construct netmask for network</entry>
7505 <entry><literal>netmask('192.168.1.5/24')</literal></entry>
7506 <entry><literal>255.255.255.0</literal></entry>
7507 </row>
7508 <row>
7509 <entry><literal><function>network</function>(<type>inet</type>)</literal></entry>
7510 <entry><type>cidr</type></entry>
7511 <entry>extract network part of address</entry>
7512 <entry><literal>network('192.168.1.5/24')</literal></entry>
7513 <entry><literal>192.168.1.0/24</literal></entry>
7514 </row>
7515 <row>
7516 <entry><literal><function>set_masklen</function>(<type>inet</type>, <type>int</type>)</literal></entry>
7517 <entry><type>inet</type></entry>
7518 <entry>set netmask length for <type>inet</type> value</entry>
7519 <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
7520 <entry><literal>192.168.1.5/16</literal></entry>
7521 </row>
7522 <row>
7523 <entry><literal><function>set_masklen</function>(<type>cidr</type>, <type>int</type>)</literal></entry>
7524 <entry><type>cidr</type></entry>
7525 <entry>set netmask length for <type>cidr</type> value</entry>
7526 <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
7527 <entry><literal>192.168.0.0/16</literal></entry>
7528 </row>
7529 <row>
7530 <entry><literal><function>text</function>(<type>inet</type>)</literal></entry>
7531 <entry><type>text</type></entry>
7532 <entry>extract IP address and netmask length as text</entry>
7533 <entry><literal>text(inet '192.168.1.5')</literal></entry>
7534 <entry><literal>192.168.1.5/32</literal></entry>
7535 </row>
7536 </tbody>
7537 </tgroup>
7538 </table>
7540 <para>
7541 Any <type>cidr</> value can be cast to <type>inet</> implicitly
7542 or explicitly; therefore, the functions shown above as operating on
7543 <type>inet</> also work on <type>cidr</> values. (Where there are
7544 separate functions for <type>inet</> and <type>cidr</>, it is because
7545 the behavior should be different for the two cases.)
7546 Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
7547 When this is done, any bits to the right of the netmask are silently zeroed
7548 to create a valid <type>cidr</> value.
7549 In addition,
7550 you can cast a text value to <type>inet</> or <type>cidr</>
7551 using normal casting syntax: for example,
7552 <literal>inet(<replaceable>expression</>)</literal> or
7553 <literal><replaceable>colname</>::cidr</literal>.
7554 </para>
7556 <para>
7557 <xref linkend="macaddr-functions-table"> shows the functions
7558 available for use with the <type>macaddr</type> type. The function
7559 <literal><function>trunc</function>(<type>macaddr</type>)</literal> returns a MAC
7560 address with the last 3 bytes set to zero. This can be used to
7561 associate the remaining prefix with a manufacturer.
7562 </para>
7564 <table id="macaddr-functions-table">
7565 <title><type>macaddr</type> Functions</title>
7566 <tgroup cols="5">
7567 <thead>
7568 <row>
7569 <entry>Function</entry>
7570 <entry>Return Type</entry>
7571 <entry>Description</entry>
7572 <entry>Example</entry>
7573 <entry>Result</entry>
7574 </row>
7575 </thead>
7576 <tbody>
7577 <row>
7578 <entry><literal><function>trunc</function>(<type>macaddr</type>)</literal></entry>
7579 <entry><type>macaddr</type></entry>
7580 <entry>set last 3 bytes to zero</entry>
7581 <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
7582 <entry><literal>12:34:56:00:00:00</literal></entry>
7583 </row>
7584 </tbody>
7585 </tgroup>
7586 </table>
7588 <para>
7589 The <type>macaddr</type> type also supports the standard relational
7590 operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
7591 lexicographical ordering.
7592 </para>
7594 </sect1>
7597 <sect1 id="functions-textsearch">
7598 <title>Full Text Search Functions and Operators</title>
7600 <para>
7601 This section outlines all the functions and operators that are available
7602 for full text searching.
7603 </para>
7605 <para>
7606 Full text search vectors and queries both use lexemes, but for different
7607 purposes. A <type>tsvector</type> represents the lexemes (tokens) parsed
7608 out of a document, with an optional position. A <type>tsquery</type>
7609 specifies a boolean condition using lexemes.
7610 </para>
7612 <para>
7613 All of the following functions that accept a configuration argument can
7614 use a textual configuration name to select a configuration. If the option
7615 is omitted the configuration specified by
7616 <varname>default_text_search_config</> is used. For more information on
7617 configuration, see <xref linkend="textsearch-tables-configuration">.
7618 </para>
7620 <sect2 id="functions-textsearch-search-operator">
7621 <title>Search</title>
7623 <para>The operator <literal>@@</> is used to perform full text
7624 searches:
7625 </para>
7627 <variablelist>
7629 <varlistentry>
7631 <indexterm>
7632 <primary>TSVECTOR @@ TSQUERY</primary>
7633 </indexterm>
7635 <term>
7636 <synopsis>
7637 <!-- why allow such combinations? -->
7638 TSVECTOR @@ TSQUERY
7639 TSQUERY @@ TSVECTOR
7640 </synopsis>
7641 </term>
7643 <listitem>
7644 <para>
7645 Returns <literal>true</literal> if <literal>TSQUERY</literal> is contained
7646 in <literal>TSVECTOR</literal>, and <literal>false</literal> if not:
7648 <programlisting>
7649 SELECT 'a fat cat sat on a mat and ate a fat rat'::tsvector @@ 'cat &amp; rat'::tsquery;
7650 ?column?
7651 ----------
7654 SELECT 'a fat cat sat on a mat and ate a fat rat'::tsvector @@ 'fat &amp; cow'::tsquery;
7655 ?column?
7656 ----------
7658 </programlisting>
7659 </para>
7661 </listitem>
7662 </varlistentry>
7664 <varlistentry>
7666 <indexterm>
7667 <primary>TEXT @@ TSQUERY</primary>
7668 </indexterm>
7670 <term>
7671 <synopsis>
7672 text @@ tsquery
7673 </synopsis>
7674 </term>
7676 <listitem>
7677 <para>
7678 Returns <literal>true</literal> if <literal>TSQUERY</literal> is contained
7679 in <literal>TEXT</literal>, and <literal>false</literal> if not:
7681 <programlisting>
7682 SELECT 'a fat cat sat on a mat and ate a fat rat'::text @@ 'cat &amp; rat'::tsquery;
7683 ?column?
7684 ----------
7687 SELECT 'a fat cat sat on a mat and ate a fat rat'::text @@ 'cat &amp; cow'::tsquery;
7688 ?column?
7689 ----------
7691 </programlisting>
7692 </para>
7693 </listitem>
7694 </varlistentry>
7696 <varlistentry>
7698 <indexterm>
7699 <primary>TEXT @@ TEXT</primary>
7700 </indexterm>
7702 <term>
7703 <synopsis>
7704 <!-- this is very confusing because there is no rule suggesting which is
7705 first. -->
7706 text @@ text
7707 </synopsis>
7708 </term>
7710 <listitem>
7711 <para>
7712 Returns <literal>true</literal> if the right
7713 argument (the query) is contained in the left argument, and
7714 <literal>false</literal> otherwise:
7716 <programlisting>
7717 SELECT 'a fat cat sat on a mat and ate a fat rat' @@ 'cat rat';
7718 ?column?
7719 ----------
7722 SELECT 'a fat cat sat on a mat and ate a fat rat' @@ 'cat cow';
7723 ?column?
7724 ----------
7726 </programlisting>
7727 </para>
7729 </listitem>
7730 </varlistentry>
7732 </variablelist>
7734 <para>
7735 For index support of full text operators consult <xref linkend="textsearch-indexes">.
7736 </para>
7738 </sect2>
7740 <sect2 id="functions-textsearch-tsvector">
7741 <title>tsvector</title>
7743 <variablelist>
7745 <varlistentry>
7747 <indexterm>
7748 <primary>to_tsvector</primary>
7749 </indexterm>
7751 <term>
7752 <synopsis>
7753 to_tsvector(<optional><replaceable class="PARAMETER">config_name</replaceable></optional>, <replaceable class="PARAMETER">document</replaceable> TEXT) returns TSVECTOR
7754 </synopsis>
7755 </term>
7757 <listitem>
7758 <para>
7759 Parses a document into tokens, reduces the tokens to lexemes, and returns a
7760 <type>tsvector</type> which lists the lexemes together with their positions in the document
7761 in lexicographic order.
7762 </para>
7764 </listitem>
7765 </varlistentry>
7767 <varlistentry>
7769 <indexterm>
7770 <primary>strip</primary>
7771 </indexterm>
7773 <term>
7774 <synopsis>
7775 strip(<replaceable class="PARAMETER">vector</replaceable> TSVECTOR) returns TSVECTOR
7776 </synopsis>
7777 </term>
7779 <listitem>
7780 <para>
7781 Returns a vector which lists the same lexemes as the given vector, but
7782 which lacks any information about where in the document each lexeme
7783 appeared. While the returned vector is useless for relevance ranking it
7784 will usually be much smaller.
7785 </para>
7786 </listitem>
7788 </varlistentry>
7790 <varlistentry>
7792 <indexterm>
7793 <primary>setweight</primary>
7794 </indexterm>
7796 <term>
7797 <synopsis>
7798 setweight(<replaceable class="PARAMETER">vector</replaceable> TSVECTOR, <replaceable class="PARAMETER">letter</replaceable>) returns TSVECTOR
7799 </synopsis>
7800 </term>
7802 <listitem>
7803 <para>
7804 This function returns a copy of the input vector in which every location
7805 has been labeled with either the letter <literal>A</literal>,
7806 <literal>B</literal>, or <literal>C</literal>, or the default label
7807 <literal>D</literal> (which is the default for new vectors
7808 and as such is usually not displayed). These labels are retained
7809 when vectors are concatenated, allowing words from different parts of a
7810 document to be weighted differently by ranking functions.
7811 </para>
7812 </listitem>
7813 </varlistentry>
7815 <varlistentry>
7817 <indexterm>
7818 <primary>tsvector concatenation</primary>
7819 </indexterm>
7821 <term>
7822 <synopsis>
7823 <replaceable class="PARAMETER">vector1</replaceable> || <replaceable class="PARAMETER">vector2</replaceable>
7824 tsvector_concat(<replaceable class="PARAMETER">vector1</replaceable> TSVECTOR, <replaceable class="PARAMETER">vector2</replaceable> TSVECTOR) returns TSVECTOR
7825 </synopsis>
7826 </term>
7828 <listitem>
7829 <para>
7830 Returns a vector which combines the lexemes and positional information of
7831 the two vectors given as arguments. Positional weight labels (described
7832 in the previous paragraph) are retained during the concatenation. This
7833 has at least two uses. First, if some sections of your document need to be
7834 parsed with different configurations than others, you can parse them
7835 separately and then concatenate the resulting vectors. Second, you can
7836 weigh words from one section of your document differently than the others
7837 by parsing the sections into separate vectors and assigning each vector
7838 a different position label with the <function>setweight()</function>
7839 function. You can then concatenate them into a single vector and provide
7840 a weights argument to the <function>ts_rank()</function> function that assigns
7841 different weights to positions with different labels.
7842 </para>
7843 </listitem>
7844 </varlistentry>
7847 <varlistentry>
7848 <indexterm>
7849 <primary>length(tsvector)</primary>
7850 </indexterm>
7852 <term>
7853 <synopsis>
7854 length(<replaceable class="PARAMETER">vector</replaceable> TSVECTOR) returns INT4
7855 </synopsis>
7856 </term>
7858 <listitem>
7859 <para>
7860 Returns the number of lexemes stored in the vector.
7861 </para>
7862 </listitem>
7863 </varlistentry>
7865 <varlistentry>
7867 <indexterm>
7868 <primary>text::tsvector</primary>
7869 </indexterm>
7871 <term>
7872 <synopsis>
7873 <replaceable>text</replaceable>::TSVECTOR returns TSVECTOR
7874 </synopsis>
7875 </term>
7877 <listitem>
7878 <para>
7879 Directly casting <type>text</type> to a <type>tsvector</type> allows you
7880 to directly inject lexemes into a vector with whatever positions and
7881 positional weights you choose to specify. The text should be formatted to
7882 match the way a vector is displayed by <literal>SELECT</literal>.
7883 <!-- TODO what a strange definition, I think something like
7884 "input format" or so should be used (and defined somewhere, didn't see
7885 it yet) -->
7886 </para>
7887 </listitem>
7888 </varlistentry>
7890 <varlistentry>
7892 <indexterm>
7893 <primary>trigger</primary>
7894 <secondary>for updating a derived tsvector column</secondary>
7895 </indexterm>
7897 <term>
7898 <synopsis>
7899 tsvector_update_trigger(<replaceable class="PARAMETER">tsvector_column_name</replaceable>, <replaceable class="PARAMETER">config_name</replaceable>, <replaceable class="PARAMETER">text_column_name</replaceable> <optional>, ... </optional>)
7900 tsvector_update_trigger_column(<replaceable class="PARAMETER">tsvector_column_name</replaceable>, <replaceable class="PARAMETER">config_column_name</replaceable>, <replaceable class="PARAMETER">text_column_name</replaceable> <optional>, ... </optional>)
7901 </synopsis>
7902 </term>
7904 <listitem>
7905 <para>
7906 Two built-in trigger functions are available to automatically update a
7907 <type>tsvector</> column from one or more textual columns. An example
7908 of their use is:
7910 <programlisting>
7911 CREATE TABLE tblMessages (
7912 strMessage text,
7913 tsv tsvector
7916 CREATE TRIGGER tsvectorupdate BEFORE INSERT OR UPDATE
7917 ON tblMessages FOR EACH ROW EXECUTE PROCEDURE
7918 tsvector_update_trigger(tsv, 'pg_catalog.english', strMessage);
7919 </programlisting>
7921 Having created this trigger, any change in <structfield>strMessage</>
7922 will be automatically reflected into <structfield>tsv</>.
7923 </para>
7925 <para>
7926 Both triggers require you to specify the text search configuration to
7927 be used to perform the conversion. For
7928 <function>tsvector_update_trigger</>, the configuration name is simply
7929 given as the second trigger argument. It must be schema-qualified as
7930 shown above, so that the trigger behavior will not change with changes
7931 in <varname>search_path</>. For
7932 <function>tsvector_update_trigger_column</>, the second trigger argument
7933 is the name of another table column, which must be of type
7934 <type>regconfig</>. This allows a per-row selection of configuration
7935 to be made.
7936 </para>
7937 </listitem>
7938 </varlistentry>
7940 <varlistentry>
7942 <indexterm>
7943 <primary>ts_stat</primary>
7944 </indexterm>
7946 <term>
7947 <synopsis>
7948 ts_stat(<replaceable class="PARAMETER">sqlquery</replaceable> text <optional>, <replaceable class="PARAMETER">weights</replaceable> text </optional>) returns SETOF statinfo
7949 </synopsis>
7950 </term>
7952 <listitem>
7953 <para>
7954 Here <type>statinfo</type> is a type, defined as:
7956 <programlisting>
7957 CREATE TYPE statinfo AS (word text, ndoc integer, nentry integer);
7958 </programlisting>
7960 and <replaceable>sqlquery</replaceable> is a text value containing a SQL query
7961 which returns a single <type>tsvector</type> column. <function>ts_stat</>
7962 executes the query and returns statistics about the resulting
7963 <type>tsvector</type> data, i.e., the number of documents, <literal>ndoc</>,
7964 and the total number of words in the collection, <literal>nentry</>. It is
7965 useful for checking your configuration and to find stop word candidates. For
7966 example, to find the ten most frequent words:
7968 <programlisting>
7969 SELECT * FROM ts_stat('SELECT vector from apod')
7970 ORDER BY ndoc DESC, nentry DESC, word
7971 LIMIT 10;
7972 </programlisting>
7974 Optionally, one can specify <replaceable>weights</replaceable> to obtain
7975 statistics about words with a specific <replaceable>weight</replaceable>:
7977 <programlisting>
7978 SELECT * FROM ts_stat('SELECT vector FROM apod','a')
7979 ORDER BY ndoc DESC, nentry DESC, word
7980 LIMIT 10;
7981 </programlisting>
7983 </para>
7984 </listitem>
7985 </varlistentry>
7987 <varlistentry>
7989 <indexterm>
7990 <primary>Btree operations for tsvector</primary>
7991 </indexterm>
7993 <term>
7994 <synopsis>
7995 TSVECTOR &lt; TSVECTOR
7996 TSVECTOR &lt;= TSVECTOR
7997 TSVECTOR = TSVECTOR
7998 TSVECTOR &gt;= TSVECTOR
7999 TSVECTOR &gt; TSVECTOR
8000 </synopsis>
8001 </term>
8003 <listitem>
8004 <para>
8005 All btree operations are defined for the <type>tsvector</type> type.
8006 <type>tsvector</>s are compared with each other using
8007 <emphasis>lexicographical</emphasis> ordering.
8008 <!-- TODO of the output representation or something else? -->
8009 </para>
8010 </listitem>
8011 </varlistentry>
8013 </variablelist>
8015 </sect2>
8017 <sect2 id="functions-textsearch-tsquery">
8018 <title>tsquery</title>
8021 <variablelist>
8023 <varlistentry>
8025 <indexterm>
8026 <primary>to_tsquery</primary>
8027 </indexterm>
8029 <term>
8030 <synopsis>
8031 to_tsquery(<optional><replaceable class="PARAMETER">config_name</replaceable></optional>, <replaceable class="PARAMETER">querytext</replaceable> text) returns TSQUERY
8032 </synopsis>
8033 </term>
8035 <listitem>
8036 <para>
8037 Accepts <replaceable>querytext</replaceable>, which should consist of single tokens
8038 separated by the boolean operators <literal>&amp;</literal> (and), <literal>|</literal>
8039 (or) and <literal>!</literal> (not), which can be grouped using parentheses.
8040 In other words, <function>to_tsquery</function> expects already parsed text.
8041 Each token is reduced to a lexeme using the specified or current configuration.
8042 A weight class can be assigned to each lexeme entry to restrict the search region
8043 (see <function>setweight</function> for an explanation). For example:
8045 <programlisting>
8046 'fat:a &amp; rats'
8047 </programlisting>
8049 The <function>to_tsquery</function> function can also accept a <literal>text
8050 string</literal>. In this case <replaceable>querytext</replaceable> should
8051 be quoted. This may be useful, for example, to use with a thesaurus
8052 dictionary. In the example below, a thesaurus contains rule <literal>supernovae
8053 stars : sn</literal>:
8055 <programlisting>
8056 SELECT to_tsquery('''supernovae stars'' &amp; !crab');
8057 to_tsquery
8058 ---------------
8059 'sn' &amp; !'crab'
8060 </programlisting>
8062 Without quotes <function>to_tsquery</function> will generate a syntax error.
8063 </para>
8065 </listitem>
8066 </varlistentry>
8070 <varlistentry>
8072 <indexterm>
8073 <primary>plainto_tsquery</primary>
8074 </indexterm>
8076 <term>
8077 <synopsis>
8078 plainto_tsquery(<optional><replaceable class="PARAMETER">config_name</replaceable></optional>, <replaceable class="PARAMETER">querytext</replaceable> text) returns TSQUERY
8079 </synopsis>
8080 </term>
8082 <listitem>
8083 <para>
8084 Transforms unformatted text <replaceable>querytext</replaceable> to <type>tsquery</type>.
8085 It is the same as <function>to_tsquery</function> but accepts <literal>text</literal>
8086 without quotes and will call the parser to break it into tokens.
8087 <function>plainto_tsquery</function> assumes the <literal>&amp;</literal> boolean
8088 operator between words and does not recognize weight classes.
8089 </para>
8090 </listitem>
8091 </varlistentry>
8095 <varlistentry>
8097 <indexterm>
8098 <primary>querytree</primary>
8099 </indexterm>
8101 <term>
8102 <synopsis>
8103 querytree(<replaceable class="PARAMETER">query</replaceable> TSQUERY) returns TEXT
8104 </synopsis>
8105 </term>
8107 <listitem>
8108 <para>
8109 This returns the query used for searching an index. It can be used to test
8110 for an empty query. The <command>SELECT</> below returns <literal>NULL</>,
8111 which corresponds to an empty query since GIN indexes do not support queries with negation
8112 <!-- TODO or "negated queries" (depending on what the correct rule is) -->
8113 (a full index scan is inefficient):
8115 <programlisting>
8116 SELECT querytree(to_tsquery('!defined'));
8117 querytree
8118 -----------
8120 </programlisting>
8121 </para>
8122 </listitem>
8123 </varlistentry>
8125 <varlistentry>
8127 <indexterm>
8128 <primary>text::tsquery casting</primary>
8129 </indexterm>
8131 <term>
8132 <synopsis>
8133 <replaceable class="PARAMETER">text</replaceable>::TSQUERY returns TSQUERY
8134 </synopsis>
8135 </term>
8137 <listitem>
8138 <para>
8139 Directly casting <replaceable>text</replaceable> to a <type>tsquery</type>
8140 allows you to directly inject lexemes into a query using whatever positions
8141 and positional weight flags you choose to specify. The text should be
8142 formatted to match the way a vector is displayed by
8143 <literal>SELECT</literal>.
8144 <!-- TODO what a strange definition, I think something like
8145 "input format" or so should be used (and defined somewhere, didn't see
8146 it yet) -->
8147 </para>
8148 </listitem>
8149 </varlistentry>
8151 <varlistentry>
8153 <indexterm>
8154 <primary>numnode</primary>
8155 </indexterm>
8157 <term>
8158 <synopsis>
8159 numnode(<replaceable class="PARAMETER">query</replaceable> TSQUERY) returns INTEGER
8160 </synopsis>
8161 </term>
8163 <listitem>
8164 <para>
8165 This returns the number of nodes in a query tree. This function can be
8166 used to determine if <replaceable>query</replaceable> is meaningful
8167 (returns &gt; 0), or contains only stop words (returns 0):
8169 <programlisting>
8170 SELECT numnode(plainto_tsquery('the any'));
8171 NOTICE: query contains only stopword(s) or does not contain lexeme(s), ignored
8172 numnode
8173 ---------
8176 SELECT numnode(plainto_tsquery('the table'));
8177 numnode
8178 ---------
8181 SELECT numnode(plainto_tsquery('long table'));
8182 numnode
8183 ---------
8185 </programlisting>
8186 </para>
8187 </listitem>
8188 </varlistentry>
8190 <varlistentry>
8192 <indexterm>
8193 <primary>TSQUERY &amp;&amp; TSQUERY</primary>
8194 </indexterm>
8196 <term>
8197 <synopsis>
8198 TSQUERY &amp;&amp; TSQUERY returns TSQUERY
8199 </synopsis>
8200 </term>
8202 <listitem>
8203 <para>
8204 Returns <literal>AND</literal>-ed TSQUERY
8205 </para>
8206 </listitem>
8207 </varlistentry>
8209 <varlistentry>
8211 <indexterm>
8212 <primary>TSQUERY || TSQUERY</primary>
8213 </indexterm>
8215 <term>
8216 <synopsis>
8217 TSQUERY || TSQUERY returns TSQUERY
8218 </synopsis>
8219 </term>
8221 <listitem>
8222 <para>
8223 Returns <literal>OR</literal>-ed TSQUERY
8224 </para>
8225 </listitem>
8226 </varlistentry>
8228 <varlistentry>
8230 <indexterm>
8231 <primary>!! TSQUERY</primary>
8232 </indexterm>
8234 <term>
8235 <synopsis>
8236 !! TSQUERY returns TSQUERY
8237 </synopsis>
8238 </term>
8240 <listitem>
8241 <para>
8242 negation of TSQUERY
8243 </para>
8244 </listitem>
8245 </varlistentry>
8247 <varlistentry>
8249 <indexterm>
8250 <primary>Btree operations for tsquery</primary>
8251 </indexterm>
8253 <term>
8254 <synopsis>
8255 TSQUERY &lt; TSQUERY
8256 TSQUERY &lt;= TSQUERY
8257 TSQUERY = TSQUERY
8258 TSQUERY &gt;= TSQUERY
8259 TSQUERY &gt; TSQUERY
8260 </synopsis>
8261 </term>
8263 <listitem>
8264 <para>
8265 All btree operations are defined for the <type>tsquery</type> type.
8266 tsqueries are compared to each other using <emphasis>lexicographical</emphasis>
8267 ordering.
8268 </para>
8269 </listitem>
8270 </varlistentry>
8272 </variablelist>
8274 <sect3 id="functions-textsearch-queryrewriting">
8275 <title>Query Rewriting</title>
8277 <para>
8278 Query rewriting is a set of functions and operators for the
8279 <type>tsquery</type> data type. It allows control at search
8280 <emphasis>query time</emphasis> without reindexing (the opposite of the
8281 thesaurus). For example, you can expand the search using synonyms
8282 (<literal>new york</>, <literal>big apple</>, <literal>nyc</>,
8283 <literal>gotham</>) or narrow the search to direct the user to some hot
8284 topic.
8285 </para>
8287 <para>
8288 The <function>ts_rewrite()</function> function changes the original query by
8289 replacing part of the query with some other string of type <type>tsquery</type>,
8290 as defined by the rewrite rule. Arguments to <function>ts_rewrite()</function>
8291 can be names of columns of type <type>tsquery</type>.
8292 </para>
8294 <programlisting>
8295 CREATE TABLE aliases (t TSQUERY PRIMARY KEY, s TSQUERY);
8296 INSERT INTO aliases VALUES('a', 'c');
8297 </programlisting>
8299 <variablelist>
8301 <varlistentry>
8303 <indexterm>
8304 <primary>ts_rewrite</primary>
8305 </indexterm>
8307 <term>
8308 <synopsis>
8309 ts_rewrite (<replaceable class="PARAMETER">query</replaceable> TSQUERY, <replaceable class="PARAMETER">target</replaceable> TSQUERY, <replaceable class="PARAMETER">sample</replaceable> TSQUERY) returns TSQUERY
8310 </synopsis>
8311 </term>
8313 <listitem>
8314 <para>
8315 <programlisting>
8316 SELECT ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'c'::tsquery);
8317 ts_rewrite
8318 ------------
8319 'b' &amp; 'c'
8320 </programlisting>
8321 </para>
8322 </listitem>
8323 </varlistentry>
8325 <varlistentry>
8327 <term>
8328 <synopsis>
8329 ts_rewrite(ARRAY[<replaceable class="PARAMETER">query</replaceable> TSQUERY, <replaceable class="PARAMETER">target</replaceable> TSQUERY, <replaceable class="PARAMETER">sample</replaceable> TSQUERY]) returns TSQUERY
8330 </synopsis>
8331 </term>
8333 <listitem>
8334 <para>
8335 <programlisting>
8336 SELECT ts_rewrite(ARRAY['a &amp; b'::tsquery, t,s]) FROM aliases;
8337 ts_rewrite
8338 ------------
8339 'b' &amp; 'c'
8340 </programlisting>
8341 </para>
8342 </listitem>
8343 </varlistentry>
8345 <varlistentry>
8347 <term>
8348 <synopsis>
8349 ts_rewrite (<replaceable class="PARAMETER">query</> TSQUERY,<literal>'SELECT target ,sample FROM test'</literal>::text) returns TSQUERY
8350 </synopsis>
8351 </term>
8353 <listitem>
8354 <para>
8355 <programlisting>
8356 SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases');
8357 ts_rewrite
8358 ------------
8359 'b' &amp; 'c'
8360 </programlisting>
8361 </para>
8362 </listitem>
8363 </varlistentry>
8365 </variablelist>
8367 <para>
8368 What if there are several instances of rewriting? For example, query
8369 <literal>'a &amp; b'</literal> can be rewritten as
8370 <literal>'b &amp; c'</literal> and <literal>'cc'</literal>.
8372 <programlisting>
8373 SELECT * FROM aliases;
8374 t | s
8375 -----------+------
8376 'a' | 'c'
8377 'x' | 'z'
8378 'a' &amp; 'b' | 'cc'
8379 </programlisting>
8381 This ambiguity can be resolved by specifying a sort order:
8383 <programlisting>
8384 SELECT ts_rewrite('a &amp; b', 'SELECT t, s FROM aliases ORDER BY t DESC');
8385 ts_rewrite
8386 ---------
8387 'cc'
8389 SELECT ts_rewrite('a &amp; b', 'SELECT t, s FROM aliases ORDER BY t ASC');
8390 ts_rewrite
8391 --------------
8392 'b' &amp; 'c'
8393 </programlisting>
8394 </para>
8396 <para>
8397 Let's consider a real-life astronomical example. We'll expand query
8398 <literal>supernovae</literal> using table-driven rewriting rules:
8400 <programlisting>
8401 CREATE TABLE aliases (t tsquery primary key, s tsquery);
8402 INSERT INTO aliases VALUES(to_tsquery('supernovae'), to_tsquery('supernovae|sn'));
8404 SELECT ts_rewrite(to_tsquery('supernovae'), 'SELECT * FROM aliases') &amp;&amp; to_tsquery('crab');
8405 ?column?
8406 -------------------------------
8407 ( 'supernova' | 'sn' ) &amp; 'crab'
8408 </programlisting>
8410 Notice, that we can change the rewriting rule online<!-- TODO maybe use another word for "online"? -->:
8412 <programlisting>
8413 UPDATE aliases SET s=to_tsquery('supernovae|sn &amp; !nebulae') WHERE t=to_tsquery('supernovae');
8414 SELECT ts_rewrite(to_tsquery('supernovae'), 'SELECT * FROM aliases') &amp;&amp; to_tsquery('crab');
8415 ?column?
8416 -----------------------------------------------
8417 'supernova' | 'sn' &amp; !'nebula' ) &amp; 'crab'
8418 </programlisting>
8419 </para>
8420 </sect3>
8422 <sect3 id="functions-textsearch-tsquery-ops">
8423 <title>Operators For tsquery</title>
8425 <para>
8426 Rewriting can be slow for many rewriting rules since it checks every rule
8427 for a possible hit. To filter out obvious non-candidate rules there are containment
8428 operators for the <type>tsquery</type> type. In the example below, we select only those
8429 rules which might contain the original query:
8431 <programlisting>
8432 SELECT ts_rewrite(ARRAY['a &amp; b'::tsquery, t,s])
8433 FROM aliases
8434 WHERE 'a &amp; b' @> t;
8435 ts_rewrite
8436 ------------
8437 'b' &amp; 'c'
8438 </programlisting>
8440 </para>
8442 <para>
8443 Two operators are defined for <type>tsquery</type>:
8444 </para>
8446 <variablelist>
8448 <varlistentry>
8450 <indexterm>
8451 <primary>TSQUERY @&gt; TSQUERY</primary>
8452 </indexterm>
8454 <term>
8455 <synopsis>
8456 TSQUERY @&gt; TSQUERY
8457 </synopsis>
8458 </term>
8460 <listitem>
8461 <para>
8462 Returns <literal>true</literal> if the right argument might be contained in left argument.
8463 </para>
8464 </listitem>
8465 </varlistentry>
8467 <varlistentry>
8469 <indexterm>
8470 <primary>tsquery &lt;@ tsquery</primary>
8471 </indexterm>
8473 <term>
8474 <synopsis>
8475 TSQUERY &lt;@ TSQUERY
8476 </synopsis>
8477 </term>
8479 <listitem>
8480 <para>
8481 Returns <literal>true</literal> if the left argument might be contained in right argument.
8482 </para>
8483 </listitem>
8484 </varlistentry>
8486 </variablelist>
8489 </sect3>
8491 <sect3 id="functions-textsearch-tsqueryindex">
8492 <title>Index For tsquery</title>
8494 <para>
8495 To speed up operators <literal>&lt;@</> and <literal>@&gt;</literal> for
8496 <type>tsquery</type> one can use a <acronym>GiST</acronym> index with
8497 a <literal>tsquery_ops</literal> opclass:
8499 <programlisting>
8500 CREATE INDEX t_idx ON aliases USING gist (t tsquery_ops);
8501 </programlisting>
8502 </para>
8504 </sect3>
8506 </sect2>
8508 </sect1>
8511 <sect1 id="functions-xml">
8512 <title>XML Functions</title>
8514 <para>
8515 The functions and function-like expressions described in this
8516 section operate on values of type <type>xml</type>. Check <xref
8517 linkend="datatype-xml"> for information about the <type>xml</type>
8518 type. The function-like expressions <function>xmlparse</function>
8519 and <function>xmlserialize</function> for converting to and from
8520 type <type>xml</type> are not repeated here. Use of many of these
8521 functions requires the installation to have been built
8522 with <command>configure --with-libxml</>.
8523 </para>
8525 <sect2>
8526 <title>Producing XML Content</title>
8528 <para>
8529 A set of functions and function-like expressions are available for
8530 producing XML content from SQL data. As such, they are
8531 particularly suitable for formatting query results into XML
8532 documents for processing in client applications.
8533 </para>
8535 <sect3>
8536 <title><literal>xmlcomment</literal></title>
8538 <indexterm>
8539 <primary>xmlcomment</primary>
8540 </indexterm>
8542 <synopsis>
8543 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8544 </synopsis>
8546 <para>
8547 The function <function>xmlcomment</function> creates an XML value
8548 containing an XML comment with the specified text as content.
8549 The text cannot contain <literal>--</literal> or end with a
8550 <literal>-</literal> so that the resulting construct is a valid
8551 XML comment. If the argument is null, the result is null.
8552 </para>
8554 <para>
8555 Example:
8556 <screen><![CDATA[
8557 SELECT xmlcomment('hello');
8559 xmlcomment
8560 --------------
8561 <!--hello-->
8562 ]]></screen>
8563 </para>
8564 </sect3>
8566 <sect3>
8567 <title><literal>xmlconcat</literal></title>
8569 <indexterm>
8570 <primary>xmlconcat</primary>
8571 </indexterm>
8573 <synopsis>
8574 <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8575 </synopsis>
8577 <para>
8578 The function <function>xmlconcat</function> concatenates a list
8579 of individual XML values to create a single value containing an
8580 XML content fragment. Null values are omitted; the result is
8581 only null if there are no nonnull arguments.
8582 </para>
8584 <para>
8585 Example:
8586 <screen><![CDATA[
8587 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8589 xmlconcat
8590 ----------------------
8591 <abc/><bar>foo</bar>
8592 ]]></screen>
8593 </para>
8595 <para>
8596 XML declarations, if present are combined as follows. If all
8597 argument values have the same XML version declaration, that
8598 version is used in the result, else no version is used. If all
8599 argument values have the standalone declaration value
8600 <quote>yes</quote>, then that value is used in the result. If
8601 all argument values have a standalone declaration value and at
8602 least one is <quote>no</quote>, then that is used in the result.
8603 Else the result will have no standalone declaration. If the
8604 result is determined to require a standalone declaration but no
8605 version declaration, a version declaration with version 1.0 will
8606 be used because XML requires an XML declaration to contain a
8607 version declaration. Encoding declarations are ignored and
8608 removed in all cases.
8609 </para>
8611 <para>
8612 Example:
8613 <screen><![CDATA[
8614 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
8616 xmlconcat
8617 -----------------------------------
8618 <?xml version="1.1"?><foo/><bar/>
8619 ]]></screen>
8620 </para>
8621 </sect3>
8623 <sect3>
8624 <title><literal>xmlelement</literal></title>
8626 <indexterm>
8627 <primary>xmlelement</primary>
8628 </indexterm>
8630 <synopsis>
8631 <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>)
8632 </synopsis>
8634 <para>
8635 The <function>xmlelement</function> expression produces an XML
8636 element with the given name, attributes, and content.
8637 </para>
8639 <para>
8640 Examples:
8641 <screen><![CDATA[
8642 SELECT xmlelement(name foo);
8644 xmlelement
8645 ------------
8646 <foo/>
8648 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8650 xmlelement
8651 ------------------
8652 <foo bar="xyz"/>
8654 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8656 xmlelement
8657 -------------------------------------
8658 <foo bar="2007-01-26">content</foo>
8659 ]]></screen>
8660 </para>
8662 <para>
8663 Element and attribute names that are not valid XML names are
8664 escaped by replacing the offending characters by the sequence
8665 <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8666 <replaceable>HHHH</replaceable> is the character's Unicode
8667 codepoint in hexadecimal notation. For example:
8668 <screen><![CDATA[
8669 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
8671 xmlelement
8672 ----------------------------------
8673 <foo_x0024_bar a_x0026_b="xyz"/>
8674 ]]></screen>
8675 </para>
8677 <para>
8678 An explicit attribute name need not be specified if the attribute
8679 value is a column reference, in which case the column's name will
8680 be used as attribute name by default. In any other case, the
8681 attribute must be given an explicit name. So this example is
8682 valid:
8683 <screen>
8684 CREATE TABLE test (a xml, b xml);
8685 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8686 </screen>
8687 But these are not:
8688 <screen>
8689 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8690 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8691 </screen>
8692 </para>
8694 <para>
8695 Element content, if specified, will be formatted according to
8696 data type. If the content is itself of type <type>xml</type>,
8697 complex XML documents can be constructed. For example:
8698 <screen><![CDATA[
8699 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8700 xmlelement(name abc),
8701 xmlcomment('test'),
8702 xmlelement(name xyz));
8704 xmlelement
8705 ----------------------------------------------
8706 <foo bar="xyz"><abc/><!--test--><xyz/></foo>
8707 ]]></screen>
8709 Content of other types will be formatted into valid XML character
8710 data. This means in particular that the characters &lt;, &gt;,
8711 and &amp; will be converted to entities. Binary data (data type
8712 <type>bytea</type>) will be represented in base64 or hex
8713 encoding, depending on the setting of the configuration parameter
8714 <xref linkend="guc-xmlbinary">. The particular behavior for
8715 individual data types is expected evolve in order to align the
8716 SQL and PostgreSQL data types with the XML Schema specification,
8717 at which point a more precise description will appear.
8718 </para>
8719 </sect3>
8721 <sect3>
8722 <title><literal>xmlforest</literal></title>
8724 <indexterm>
8725 <primary>xmlforest</primary>
8726 </indexterm>
8728 <synopsis>
8729 <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8730 </synopsis>
8732 <para>
8733 The <function>xmlforest</function> expression produces an XML
8734 forest (sequence) of elements using the given names and content.
8735 </para>
8737 <para>
8738 Examples:
8739 <screen><![CDATA[
8740 SELECT xmlforest('abc' AS foo, 123 AS bar);
8742 xmlforest
8743 ------------------------------
8744 <foo>abc</foo><bar>123</bar>
8747 SELECT xmlforest(table_name, column_name) FROM information_schema.columns WHERE table_schema = 'pg_catalog';
8749 xmlforest
8750 -------------------------------------------------------------------------------------------
8751 <table_name>pg_authid</table_name><column_name>rolname</column_name>
8752 <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8754 ]]></screen>
8756 As seen in the second example, the element name can be omitted if
8757 the content value is a column reference, in which case the column
8758 name is used by default. Otherwise, a name must be specified.
8759 </para>
8761 <para>
8762 Element names that are not valid XML names are escaped as shown
8763 for <function>xmlelement</function> above. Similarly, content
8764 data is escaped to make valid XML content, unless it is already
8765 of type <type>xml</type>.
8766 </para>
8768 <para>
8769 Note that XML forests are not valid XML documents if they consist
8770 of more than one element. So it might be useful to wrap
8771 <function>xmlforest</function> expressions in
8772 <function>xmlelement</function>.
8773 </para>
8774 </sect3>
8776 <sect3>
8777 <title><literal>xmlpi</literal></title>
8779 <indexterm>
8780 <primary>xmlpi</primary>
8781 </indexterm>
8783 <synopsis>
8784 <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
8785 </synopsis>
8787 <para>
8788 The <function>xmlpi</function> expression creates an XML
8789 processing instruction. The content, if present, must not
8790 contain the character sequence <literal>?&gt;</literal>.
8791 </para>
8793 <para>
8794 Example:
8795 <screen><![CDATA[
8796 SELECT xmlpi(name php, 'echo "hello world";');
8798 xmlpi
8799 -----------------------------
8800 <?php echo "hello world";?>
8801 ]]></screen>
8802 </para>
8803 </sect3>
8805 <sect3>
8806 <title><literal>xmlroot</literal></title>
8808 <indexterm>
8809 <primary>xmlroot</primary>
8810 </indexterm>
8812 <synopsis>
8813 <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable>|no value <optional>, standalone yes|no|no value</optional>)
8814 </synopsis>
8816 <para>
8817 The <function>xmlroot</function> expression alters the properties
8818 of the root node of an XML value. If a version is specified,
8819 this replaces the value in the version declaration, if a
8820 standalone value is specified, this replaces the value in the
8821 standalone declaration.
8822 </para>
8824 <para>
8825 <screen><![CDATA[
8826 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'), version '1.0', standalone yes);
8828 xmlroot
8829 ----------------------------------------
8830 <?xml version="1.0" standalone="yes"?>
8831 <content>abc</content>
8832 ]]></screen>
8833 </para>
8834 </sect3>
8836 <sect3>
8837 <title>XML Predicates</title>
8839 <indexterm>
8840 <primary>IS DOCUMENT</primary>
8841 </indexterm>
8843 <synopsis>
8844 <replaceable>xml</replaceable> IS DOCUMENT
8845 </synopsis>
8847 <para>
8848 The expression <literal>IS DOCUMENT</literal> returns true if the
8849 argument XML value is a proper XML document, false if it is not
8850 (that is, it is a content fragment), or null if the argument is
8851 null. See <xref linkend="datatype-xml"> about the difference
8852 between documents and content fragments.
8853 </para>
8854 </sect3>
8855 </sect2>
8857 <sect2 id="functions-xml-processing">
8858 <title>Processing XML</title>
8860 <indexterm>
8861 <primary>XPath</primary>
8862 </indexterm>
8864 <para>
8865 To process values of data type <type>xml</type>, PostgreSQL offers
8866 the function <function>xpath</function>, which evaluates XPath 1.0
8867 expressions.
8868 </para>
8870 <synopsis>
8871 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable><optional>, <replaceable>nsarray</replaceable></optional>)
8872 </synopsis>
8874 <para>
8875 The function <function>xpath</function> evaluates the XPath
8876 expression <replaceable>xpath</replaceable> against the XML value
8877 <replaceable>xml</replaceable>. It returns an array of XML values
8878 corresponding to the node set produced by the XPath expression.
8879 </para>
8881 <para>
8882 The third argument of the function is an array of namespace
8883 mappings. This array should be a two-dimensional array with the
8884 length of the second axis being equal to 2 (i.e., it should be an
8885 array of arrays, each of which consists of exactly 2 elements).
8886 The first element of each array entry is the namespace name, the
8887 second the namespace URI.
8888 </para>
8890 <para>
8891 Example:
8892 <screen><![CDATA[
8893 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', ARRAY[ARRAY['my', 'http://example.com']]);
8894 xpath
8895 --------
8896 {test}
8897 (1 row)
8898 ]]></screen>
8899 </para>
8900 </sect2>
8902 <sect2 id="functions-xml-mapping">
8903 <title>Mapping Tables to XML</title>
8905 <indexterm zone="functions-xml-mapping">
8906 <primary>XML export</primary>
8907 </indexterm>
8909 <para>
8910 The following functions map the contents of relational tables to
8911 XML values. They can be thought of as XML export functionality.
8912 <synopsis>
8913 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8914 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
8915 cursor_to_xml(cursor refcursor, count int, nulls boolean, tableforest boolean, targetns text)
8916 </synopsis>
8917 The return type of each function is <type>xml</type>.
8918 </para>
8920 <para>
8921 <function>table_to_xml</function> maps the content of the named
8922 table, passed as parameter <parameter>tbl</parameter>. The
8923 <type>regclass</type> accepts strings identifying tables using the
8924 usual notation, including optional schema qualifications and
8925 double quotes. <function>query_to_xml</function> executes the
8926 query whose text is passed as parameter
8927 <parameter>query</parameter> and maps the result set.
8928 <function>cursor_to_xml</function> fetches the indicated number of
8929 rows from the cursor specified by the parameter
8930 <parameter>cursor</parameter>. This variant is recommendable if
8931 large tables have to be mapped, because the result value is built
8932 up in memory by each function.
8933 </para>
8935 <para>
8936 If <parameter>tableforest</parameter> is false, then the resulting
8937 XML document looks like this:
8938 <screen><![CDATA[
8939 <tablename>
8940 <row>
8941 <columnname1>data</columnname1>
8942 <columnname2>data</columnname2>
8943 </row>
8945 <row>
8947 </row>
8950 </tablename>
8951 ]]></screen>
8953 If <parameter>tableforest</parameter> is true, the result is an
8954 XML content fragment that looks like this:
8955 <screen><![CDATA[
8956 <tablename>
8957 <columnname1>data</columnname1>
8958 <columnname2>data</columnname2>
8959 </tablename>
8961 <tablename>
8963 </tablename>
8966 ]]></screen>
8968 If no table name is avaible, that is, when mapping a query or a
8969 cursor, the string <literal>table</literal> is used in the first
8970 format, <literal>row</literal> in the second format.
8971 </para>
8973 <para>
8974 The choice between these formats is up to the user. The first
8975 format is a proper XML document, which will be important in many
8976 applications. The second format tends to be more useful in the
8977 <function>cursor_to_xml</function> function if the result values are to be
8978 reassembled into one document later on. The functions for
8979 producing XML content discussed above, in particular
8980 <function>xmlelement</function>, can be used to alter the results
8981 to taste.
8982 </para>
8984 <para>
8985 The data values are mapped in the same way as described for the
8986 function <function>xmlelement</function> above.
8987 </para>
8989 <para>
8990 The parameter <parameter>nulls</parameter> determines whether null
8991 values should be included in the output. If true, null values in
8992 columns are represented as
8993 <screen><![CDATA[
8994 <columnname xsi:nil="true"/>
8995 ]]></screen>
8996 where <literal>xsi</literal> is the XML namespace prefix for XML
8997 Schema Instance. An appropriate namespace declaration will be
8998 added to the result value. If false, columns containing null
8999 values are simply omitted from the output.
9000 </para>
9002 <para>
9003 The parameter <parameter>targetns</parameter> specifies the
9004 desired XML namespace of the result. If no particular namespace
9005 is wanted, an empty string should be passed.
9006 </para>
9008 <para>
9009 The following functions return XML Schema documents describing the
9010 mappings made by the data mappings produced by the corresponding
9011 functions above.
9012 <synopsis>
9013 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9014 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9015 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
9016 </synopsis>
9017 It is essential that the same parameters are passed in order to
9018 obtain matching XML data mappings and XML Schema documents.
9019 </para>
9021 <para>
9022 The following functions produce XML data mappings and the
9023 corresponding XML Schema in one document (or forest), linked
9024 together. They can be useful where self-contained and
9025 self-describing results are wanted.
9026 <synopsis>
9027 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
9028 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
9029 </synopsis>
9030 </para>
9032 <para>
9033 In addition, the following functions are available to produce
9034 analogous mappings of entire schemas or the entire current
9035 database.
9036 <synopsis>
9037 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
9038 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9039 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
9041 database_to_xml(nulls boolean, tableforest boolean, targetns text)
9042 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
9043 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
9044 </synopsis>
9046 Note that these potentially produce a lot of data, which needs to
9047 be built up in memory. When requesting content mappings of large
9048 schemas or databases, it may be worthwhile to consider mapping the
9049 tables separately instead, possibly even through a cursor.
9050 </para>
9052 <para>
9053 The result of a schema content mapping looks like this:
9055 <screen><![CDATA[
9056 <schemaname>
9058 table1-mapping
9060 table2-mapping
9064 </schemaname>]]></screen>
9066 where the format of a table mapping depends on the
9067 <parameter>tableforest</parameter> parameter as explained above.
9068 </para>
9070 <para>
9071 The result of a database content mapping looks like this:
9073 <screen><![CDATA[
9074 <dbname>
9076 <schema1name>
9078 </schema1name>
9080 <schema2name>
9082 </schema2name>
9086 </dbname>]]></screen>
9088 where the schema mapping is as above.
9089 </para>
9091 <para>
9092 As an example for using the output produced by these functions,
9093 <xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
9094 converts the output of
9095 <function>table_to_xml_and_xmlschema</function> to an HTML
9096 document containing a tabular rendition of the table data. In a
9097 similar manner, the result data of these functions can be
9098 converted into other XML-based formats.
9099 </para>
9101 <figure id="xslt-xml-html">
9102 <title>XSLT stylesheet for converting SQL/XML output to HTML</title>
9103 <programlisting><![CDATA[
9104 <?xml version="1.0"?>
9105 <xsl:stylesheet version="1.0"
9106 xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
9107 xmlns:xsd="http://www.w3.org/2001/XMLSchema"
9108 xmlns="http://www.w3.org/1999/xhtml"
9111 <xsl:output method="xml"
9112 doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
9113 doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
9114 indent="yes"/>
9116 <xsl:template match="/*">
9117 <xsl:variable name="schema" select="//xsd:schema"/>
9118 <xsl:variable name="tabletypename"
9119 select="$schema/xsd:element[@name=name(current())]/@type"/>
9120 <xsl:variable name="rowtypename"
9121 select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
9123 <html>
9124 <head>
9125 <title><xsl:value-of select="name(current())"/></title>
9126 </head>
9127 <body>
9128 <table>
9129 <tr>
9130 <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
9131 <th><xsl:value-of select="."/></th>
9132 </xsl:for-each>
9133 </tr>
9135 <xsl:for-each select="row">
9136 <tr>
9137 <xsl:for-each select="*">
9138 <td><xsl:value-of select="."/></td>
9139 </xsl:for-each>
9140 </tr>
9141 </xsl:for-each>
9142 </table>
9143 </body>
9144 </html>
9145 </xsl:template>
9147 </xsl:stylesheet>
9148 ]]></programlisting>
9149 </figure>
9150 </sect2>
9151 </sect1>
9154 <sect1 id="functions-sequence">
9155 <title>Sequence Manipulation Functions</title>
9157 <indexterm>
9158 <primary>sequence</primary>
9159 </indexterm>
9160 <indexterm>
9161 <primary>nextval</primary>
9162 </indexterm>
9163 <indexterm>
9164 <primary>currval</primary>
9165 </indexterm>
9166 <indexterm>
9167 <primary>lastval</primary>
9168 </indexterm>
9169 <indexterm>
9170 <primary>setval</primary>
9171 </indexterm>
9173 <para>
9174 This section describes <productname>PostgreSQL</productname>'s
9175 functions for operating on <firstterm>sequence objects</firstterm>.
9176 Sequence objects (also called sequence generators or just
9177 sequences) are special single-row tables created with <xref
9178 linkend="sql-createsequence" endterm="sql-createsequence-title">.
9179 A sequence object is usually used to generate unique identifiers
9180 for rows of a table. The sequence functions, listed in <xref
9181 linkend="functions-sequence-table">, provide simple, multiuser-safe
9182 methods for obtaining successive sequence values from sequence
9183 objects.
9184 </para>
9186 <table id="functions-sequence-table">
9187 <title>Sequence Functions</title>
9188 <tgroup cols="3">
9189 <thead>
9190 <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
9191 </thead>
9193 <tbody>
9194 <row>
9195 <entry><literal><function>currval</function>(<type>regclass</type>)</literal></entry>
9196 <entry><type>bigint</type></entry>
9197 <entry>Return value most recently obtained with
9198 <function>nextval</function> for specified sequence</entry>
9199 </row>
9200 <row>
9201 <entry><literal><function>nextval</function>(<type>regclass</type>)</literal></entry>
9202 <entry><type>bigint</type></entry>
9203 <entry>Advance sequence and return new value</entry>
9204 </row>
9205 <row>
9206 <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>)</literal></entry>
9207 <entry><type>bigint</type></entry>
9208 <entry>Set sequence's current value</entry>
9209 </row>
9210 <row>
9211 <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</literal></entry>
9212 <entry><type>bigint</type></entry>
9213 <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
9214 </row>
9215 </tbody>
9216 </tgroup>
9217 </table>
9219 <para>
9220 The sequence to be operated on by a sequence-function call is specified by
9221 a <type>regclass</> argument, which is just the OID of the sequence in the
9222 <structname>pg_class</> system catalog. You do not have to look up the
9223 OID by hand, however, since the <type>regclass</> data type's input
9224 converter will do the work for you. Just write the sequence name enclosed
9225 in single quotes, so that it looks like a literal constant. To
9226 achieve some compatibility with the handling of ordinary
9227 <acronym>SQL</acronym> names, the string will be converted to lowercase
9228 unless it contains double quotes around the sequence name. Thus:
9229 <programlisting>
9230 nextval('foo') <lineannotation>operates on sequence <literal>foo</literal></>
9231 nextval('FOO') <lineannotation>operates on sequence <literal>foo</literal></>
9232 nextval('"Foo"') <lineannotation>operates on sequence <literal>Foo</literal></>
9233 </programlisting>
9234 The sequence name can be schema-qualified if necessary:
9235 <programlisting>
9236 nextval('myschema.foo') <lineannotation>operates on <literal>myschema.foo</literal></>
9237 nextval('"myschema".foo') <lineannotation>same as above</lineannotation>
9238 nextval('foo') <lineannotation>searches search path for <literal>foo</literal></>
9239 </programlisting>
9240 See <xref linkend="datatype-oid"> for more information about
9241 <type>regclass</>.
9242 </para>
9244 <note>
9245 <para>
9246 Before <productname>PostgreSQL</productname> 8.1, the arguments of the
9247 sequence functions were of type <type>text</>, not <type>regclass</>, and
9248 the above-described conversion from a text string to an OID value would
9249 happen at run time during each call. For backwards compatibility, this
9250 facility still exists, but internally it is now handled as an implicit
9251 coercion from <type>text</> to <type>regclass</> before the function is
9252 invoked.
9253 </para>
9255 <para>
9256 When you write the argument of a sequence function as an unadorned
9257 literal string, it becomes a constant of type <type>regclass</>.
9258 Since this is really just an OID, it will track the originally
9259 identified sequence despite later renaming, schema reassignment,
9260 etc. This <quote>early binding</> behavior is usually desirable for
9261 sequence references in column defaults and views. But sometimes you will
9262 want <quote>late binding</> where the sequence reference is resolved
9263 at run time. To get late-binding behavior, force the constant to be
9264 stored as a <type>text</> constant instead of <type>regclass</>:
9265 <programlisting>
9266 nextval('foo'::text) <lineannotation><literal>foo</literal> is looked up at runtime</>
9267 </programlisting>
9268 Note that late binding was the only behavior supported in
9269 <productname>PostgreSQL</productname> releases before 8.1, so you
9270 might need to do this to preserve the semantics of old applications.
9271 </para>
9273 <para>
9274 Of course, the argument of a sequence function can be an expression
9275 as well as a constant. If it is a text expression then the implicit
9276 coercion will result in a run-time lookup.
9277 </para>
9278 </note>
9280 <para>
9281 The available sequence functions are:
9283 <variablelist>
9284 <varlistentry>
9285 <term><function>nextval</function></term>
9286 <listitem>
9287 <para>
9288 Advance the sequence object to its next value and return that
9289 value. This is done atomically: even if multiple sessions
9290 execute <function>nextval</function> concurrently, each will safely receive
9291 a distinct sequence value.
9292 </para>
9293 </listitem>
9294 </varlistentry>
9296 <varlistentry>
9297 <term><function>currval</function></term>
9298 <listitem>
9299 <para>
9300 Return the value most recently obtained by <function>nextval</function>
9301 for this sequence in the current session. (An error is
9302 reported if <function>nextval</function> has never been called for this
9303 sequence in this session.) Notice that because this is returning
9304 a session-local value, it gives a predictable answer whether or not
9305 other sessions have executed <function>nextval</function> since the
9306 current session did.
9307 </para>
9308 </listitem>
9309 </varlistentry>
9311 <varlistentry>
9312 <term><function>lastval</function></term>
9313 <listitem>
9314 <para>
9315 Return the value most recently returned by
9316 <function>nextval</> in the current session. This function is
9317 identical to <function>currval</function>, except that instead
9318 of taking the sequence name as an argument it fetches the
9319 value of the last sequence that <function>nextval</function>
9320 was used on in the current session. It is an error to call
9321 <function>lastval</function> if <function>nextval</function>
9322 has not yet been called in the current session.
9323 </para>
9324 </listitem>
9325 </varlistentry>
9327 <varlistentry>
9328 <term><function>setval</function></term>
9329 <listitem>
9330 <para>
9331 Reset the sequence object's counter value. The two-parameter
9332 form sets the sequence's <literal>last_value</literal> field to the specified
9333 value and sets its <literal>is_called</literal> field to <literal>true</literal>,
9334 meaning that the next <function>nextval</function> will advance the sequence
9335 before returning a value. In the three-parameter form,
9336 <literal>is_called</literal> can be set either <literal>true</literal> or
9337 <literal>false</literal>. If it's set to <literal>false</literal>,
9338 the next <function>nextval</function> will return exactly the specified
9339 value, and sequence advancement commences with the following
9340 <function>nextval</function>. For example,
9342 <screen>
9343 SELECT setval('foo', 42); <lineannotation>Next <function>nextval</> will return 43</lineannotation>
9344 SELECT setval('foo', 42, true); <lineannotation>Same as above</lineannotation>
9345 SELECT setval('foo', 42, false); <lineannotation>Next <function>nextval</> will return 42</lineannotation>
9346 </screen>
9348 The result returned by <function>setval</function> is just the value of its
9349 second argument.
9350 </para>
9351 </listitem>
9352 </varlistentry>
9353 </variablelist>
9354 </para>
9356 <para>
9357 If a sequence object has been created with default parameters,
9358 <function>nextval</function> calls on it will return successive values
9359 beginning with 1. Other behaviors can be obtained by using
9360 special parameters in the <xref linkend="sql-createsequence" endterm="sql-createsequence-title"> command;
9361 see its command reference page for more information.
9362 </para>
9364 <important>
9365 <para>
9366 To avoid blocking of concurrent transactions that obtain numbers from the
9367 same sequence, a <function>nextval</function> operation is never rolled back;
9368 that is, once a value has been fetched it is considered used, even if the
9369 transaction that did the <function>nextval</function> later aborts. This means
9370 that aborted transactions might leave unused <quote>holes</quote> in the
9371 sequence of assigned values. <function>setval</function> operations are never
9372 rolled back, either.
9373 </para>
9374 </important>
9376 </sect1>
9379 <sect1 id="functions-conditional">
9380 <title>Conditional Expressions</title>
9382 <indexterm>
9383 <primary>CASE</primary>
9384 </indexterm>
9386 <indexterm>
9387 <primary>conditional expression</primary>
9388 </indexterm>
9390 <para>
9391 This section describes the <acronym>SQL</acronym>-compliant conditional expressions
9392 available in <productname>PostgreSQL</productname>.
9393 </para>
9395 <tip>
9396 <para>
9397 If your needs go beyond the capabilities of these conditional
9398 expressions you might want to consider writing a stored procedure
9399 in a more expressive programming language.
9400 </para>
9401 </tip>
9403 <sect2>
9404 <title><literal>CASE</></title>
9406 <para>
9407 The <acronym>SQL</acronym> <token>CASE</token> expression is a
9408 generic conditional expression, similar to if/else statements in
9409 other languages:
9411 <synopsis>
9412 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
9413 <optional>WHEN ...</optional>
9414 <optional>ELSE <replaceable>result</replaceable></optional>
9416 </synopsis>
9418 <token>CASE</token> clauses can be used wherever
9419 an expression is valid. <replaceable>condition</replaceable> is an
9420 expression that returns a <type>boolean</type> result. If the result is true
9421 then the value of the <token>CASE</token> expression is the
9422 <replaceable>result</replaceable> that follows the condition. If the result is false any
9423 subsequent <token>WHEN</token> clauses are searched in the same
9424 manner. If no <token>WHEN</token>
9425 <replaceable>condition</replaceable> is true then the value of the
9426 case expression is the <replaceable>result</replaceable> in the
9427 <token>ELSE</token> clause. If the <token>ELSE</token> clause is
9428 omitted and no condition matches, the result is null.
9429 </para>
9431 <para>
9432 An example:
9433 <screen>
9434 SELECT * FROM test;
9443 SELECT a,
9444 CASE WHEN a=1 THEN 'one'
9445 WHEN a=2 THEN 'two'
9446 ELSE 'other'
9448 FROM test;
9450 a | case
9451 ---+-------
9452 1 | one
9453 2 | two
9454 3 | other
9455 </screen>
9456 </para>
9458 <para>
9459 The data types of all the <replaceable>result</replaceable>
9460 expressions must be convertible to a single output type.
9461 See <xref linkend="typeconv-union-case"> for more detail.
9462 </para>
9464 <para>
9465 The following <quote>simple</quote> <token>CASE</token> expression is a
9466 specialized variant of the general form above:
9468 <synopsis>
9469 CASE <replaceable>expression</replaceable>
9470 WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
9471 <optional>WHEN ...</optional>
9472 <optional>ELSE <replaceable>result</replaceable></optional>
9474 </synopsis>
9477 <replaceable>expression</replaceable> is computed and compared to
9478 all the <replaceable>value</replaceable> specifications in the
9479 <token>WHEN</token> clauses until one is found that is equal. If
9480 no match is found, the <replaceable>result</replaceable> in the
9481 <token>ELSE</token> clause (or a null value) is returned. This is similar
9482 to the <function>switch</function> statement in C.
9483 </para>
9485 <para>
9486 The example above can be written using the simple
9487 <token>CASE</token> syntax:
9488 <screen>
9489 SELECT a,
9490 CASE a WHEN 1 THEN 'one'
9491 WHEN 2 THEN 'two'
9492 ELSE 'other'
9494 FROM test;
9496 a | case
9497 ---+-------
9498 1 | one
9499 2 | two
9500 3 | other
9501 </screen>
9502 </para>
9504 <para>
9505 A <token>CASE</token> expression does not evaluate any subexpressions
9506 that are not needed to determine the result. For example, this is a
9507 possible way of avoiding a division-by-zero failure:
9508 <programlisting>
9509 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
9510 </programlisting>
9511 </para>
9512 </sect2>
9514 <sect2>
9515 <title><literal>COALESCE</></title>
9517 <indexterm>
9518 <primary>COALESCE</primary>
9519 </indexterm>
9521 <indexterm>
9522 <primary>NVL</primary>
9523 </indexterm>
9525 <indexterm>
9526 <primary>IFNULL</primary>
9527 </indexterm>
9529 <synopsis>
9530 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9531 </synopsis>
9533 <para>
9534 The <function>COALESCE</function> function returns the first of its
9535 arguments that is not null. Null is returned only if all arguments
9536 are null. It is often used to substitute a default value for
9537 null values when data is retrieved for display, for example:
9538 <programlisting>
9539 SELECT COALESCE(description, short_description, '(none)') ...
9540 </programlisting>
9541 </para>
9543 <para>
9544 Like a <token>CASE</token> expression, <function>COALESCE</function> will
9545 not evaluate arguments that are not needed to determine the result;
9546 that is, arguments to the right of the first non-null argument are
9547 not evaluated. This SQL-standard function provides capabilities similar
9548 to <function>NVL</> and <function>IFNULL</>, which are used in some other
9549 database systems.
9550 </para>
9551 </sect2>
9553 <sect2>
9554 <title><literal>NULLIF</></title>
9556 <indexterm>
9557 <primary>NULLIF</primary>
9558 </indexterm>
9560 <synopsis>
9561 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
9562 </synopsis>
9564 <para>
9565 The <function>NULLIF</function> function returns a null value if
9566 <replaceable>value1</replaceable> and <replaceable>value2</replaceable>
9567 are equal; otherwise it returns <replaceable>value1</replaceable>.
9568 This can be used to perform the inverse operation of the
9569 <function>COALESCE</function> example given above:
9570 <programlisting>
9571 SELECT NULLIF(value, '(none)') ...
9572 </programlisting>
9573 </para>
9574 <para>
9575 If <replaceable>value1</replaceable> is <literal>(none)</>, return a null,
9576 otherwise return <replaceable>value1</replaceable>.
9577 </para>
9579 </sect2>
9581 <sect2>
9582 <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
9584 <indexterm>
9585 <primary>GREATEST</primary>
9586 </indexterm>
9587 <indexterm>
9588 <primary>LEAST</primary>
9589 </indexterm>
9591 <synopsis>
9592 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9593 </synopsis>
9594 <synopsis>
9595 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9596 </synopsis>
9598 <para>
9599 The <function>GREATEST</> and <function>LEAST</> functions select the
9600 largest or smallest value from a list of any number of expressions.
9601 The expressions must all be convertible to a common data type, which
9602 will be the type of the result
9603 (see <xref linkend="typeconv-union-case"> for details). NULL values
9604 in the list are ignored. The result will be NULL only if all the
9605 expressions evaluate to NULL.
9606 </para>
9608 <para>
9609 Note that <function>GREATEST</> and <function>LEAST</> are not in
9610 the SQL standard, but are a common extension.
9611 </para>
9612 </sect2>
9613 </sect1>
9616 <sect1 id="functions-array">
9617 <title>Array Functions and Operators</title>
9619 <para>
9620 <xref linkend="array-operators-table"> shows the operators
9621 available for <type>array</type> types.
9622 </para>
9624 <table id="array-operators-table">
9625 <title><type>array</type> Operators</title>
9626 <tgroup cols="4">
9627 <thead>
9628 <row>
9629 <entry>Operator</entry>
9630 <entry>Description</entry>
9631 <entry>Example</entry>
9632 <entry>Result</entry>
9633 </row>
9634 </thead>
9635 <tbody>
9636 <row>
9637 <entry> <literal>=</literal> </entry>
9638 <entry>equal</entry>
9639 <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
9640 <entry><literal>t</literal></entry>
9641 </row>
9643 <row>
9644 <entry> <literal>&lt;&gt;</literal> </entry>
9645 <entry>not equal</entry>
9646 <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
9647 <entry><literal>t</literal></entry>
9648 </row>
9650 <row>
9651 <entry> <literal>&lt;</literal> </entry>
9652 <entry>less than</entry>
9653 <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
9654 <entry><literal>t</literal></entry>
9655 </row>
9657 <row>
9658 <entry> <literal>&gt;</literal> </entry>
9659 <entry>greater than</entry>
9660 <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
9661 <entry><literal>t</literal></entry>
9662 </row>
9664 <row>
9665 <entry> <literal>&lt;=</literal> </entry>
9666 <entry>less than or equal</entry>
9667 <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
9668 <entry><literal>t</literal></entry>
9669 </row>
9671 <row>
9672 <entry> <literal>&gt;=</literal> </entry>
9673 <entry>greater than or equal</entry>
9674 <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
9675 <entry><literal>t</literal></entry>
9676 </row>
9678 <row>
9679 <entry> <literal>@&gt;</literal> </entry>
9680 <entry>contains</entry>
9681 <entry><literal>ARRAY[1,4,3] @&gt; ARRAY[3,1]</literal></entry>
9682 <entry><literal>t</literal></entry>
9683 </row>
9685 <row>
9686 <entry> <literal>&lt;@</literal> </entry>
9687 <entry>is contained by</entry>
9688 <entry><literal>ARRAY[2,7] &lt;@ ARRAY[1,7,4,2,6]</literal></entry>
9689 <entry><literal>t</literal></entry>
9690 </row>
9692 <row>
9693 <entry> <literal>&amp;&amp;</literal> </entry>
9694 <entry>overlap (have elements in common)</entry>
9695 <entry><literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal></entry>
9696 <entry><literal>t</literal></entry>
9697 </row>
9699 <row>
9700 <entry> <literal>||</literal> </entry>
9701 <entry>array-to-array concatenation</entry>
9702 <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
9703 <entry><literal>{1,2,3,4,5,6}</literal></entry>
9704 </row>
9706 <row>
9707 <entry> <literal>||</literal> </entry>
9708 <entry>array-to-array concatenation</entry>
9709 <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
9710 <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
9711 </row>
9713 <row>
9714 <entry> <literal>||</literal> </entry>
9715 <entry>element-to-array concatenation</entry>
9716 <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
9717 <entry><literal>{3,4,5,6}</literal></entry>
9718 </row>
9720 <row>
9721 <entry> <literal>||</literal> </entry>
9722 <entry>array-to-element concatenation</entry>
9723 <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
9724 <entry><literal>{4,5,6,7}</literal></entry>
9725 </row>
9726 </tbody>
9727 </tgroup>
9728 </table>
9730 <para>
9731 Array comparisons compare the array contents element-by-element,
9732 using the default B-Tree comparison function for the element data type.
9733 In multidimensional arrays the elements are visited in row-major order
9734 (last subscript varies most rapidly).
9735 If the contents of two arrays are equal but the dimensionality is
9736 different, the first difference in the dimensionality information
9737 determines the sort order. (This is a change from versions of
9738 <productname>PostgreSQL</> prior to 8.2: older versions would claim
9739 that two arrays with the same contents were equal, even if the
9740 number of dimensions or subscript ranges were different.)
9741 </para>
9743 <para>
9744 See <xref linkend="arrays"> for more details about array operator
9745 behavior.
9746 </para>
9748 <para>
9749 <xref linkend="array-functions-table"> shows the functions
9750 available for use with array types. See <xref linkend="arrays">
9751 for more discussion and examples of the use of these functions.
9752 </para>
9754 <table id="array-functions-table">
9755 <title><type>array</type> Functions</title>
9756 <tgroup cols="5">
9757 <thead>
9758 <row>
9759 <entry>Function</entry>
9760 <entry>Return Type</entry>
9761 <entry>Description</entry>
9762 <entry>Example</entry>
9763 <entry>Result</entry>
9764 </row>
9765 </thead>
9766 <tbody>
9767 <row>
9768 <entry>
9769 <literal>
9770 <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
9771 </literal>
9772 </entry>
9773 <entry><type>anyarray</type></entry>
9774 <entry>append an element to the end of an array</entry>
9775 <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
9776 <entry><literal>{1,2,3}</literal></entry>
9777 </row>
9778 <row>
9779 <entry>
9780 <literal>
9781 <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
9782 </literal>
9783 </entry>
9784 <entry><type>anyarray</type></entry>
9785 <entry>concatenate two arrays</entry>
9786 <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
9787 <entry><literal>{1,2,3,4,5}</literal></entry>
9788 </row>
9789 <row>
9790 <entry>
9791 <literal>
9792 <function>array_dims</function>(<type>anyarray</type>)
9793 </literal>
9794 </entry>
9795 <entry><type>text</type></entry>
9796 <entry>returns a text representation of array's dimensions</entry>
9797 <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9798 <entry><literal>[1:2][1:3]</literal></entry>
9799 </row>
9800 <row>
9801 <entry>
9802 <literal>
9803 <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
9804 </literal>
9805 </entry>
9806 <entry><type>int</type></entry>
9807 <entry>returns lower bound of the requested array dimension</entry>
9808 <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
9809 <entry><literal>0</literal></entry>
9810 </row>
9811 <row>
9812 <entry>
9813 <literal>
9814 <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
9815 </literal>
9816 </entry>
9817 <entry><type>anyarray</type></entry>
9818 <entry>append an element to the beginning of an array</entry>
9819 <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
9820 <entry><literal>{1,2,3}</literal></entry>
9821 </row>
9822 <row>
9823 <entry>
9824 <literal>
9825 <function>array_to_string</function>(<type>anyarray</type>, <type>text</type>)
9826 </literal>
9827 </entry>
9828 <entry><type>text</type></entry>
9829 <entry>concatenates array elements using provided delimiter</entry>
9830 <entry><literal>array_to_string(ARRAY[1, 2, 3], '~^~')</literal></entry>
9831 <entry><literal>1~^~2~^~3</literal></entry>
9832 </row>
9833 <row>
9834 <entry>
9835 <literal>
9836 <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
9837 </literal>
9838 </entry>
9839 <entry><type>int</type></entry>
9840 <entry>returns upper bound of the requested array dimension</entry>
9841 <entry><literal>array_upper(ARRAY[1,2,3,4], 1)</literal></entry>
9842 <entry><literal>4</literal></entry>
9843 </row>
9844 <row>
9845 <entry>
9846 <literal>
9847 <function>string_to_array</function>(<type>text</type>, <type>text</type>)
9848 </literal>
9849 </entry>
9850 <entry><type>text[]</type></entry>
9851 <entry>splits string into array elements using provided delimiter</entry>
9852 <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~')</literal></entry>
9853 <entry><literal>{xx,yy,zz}</literal></entry>
9854 </row>
9855 </tbody>
9856 </tgroup>
9857 </table>
9858 </sect1>
9860 <sect1 id="functions-aggregate">
9861 <title>Aggregate Functions</title>
9863 <indexterm zone="functions-aggregate">
9864 <primary>aggregate function</primary>
9865 <secondary>built-in</secondary>
9866 </indexterm>
9868 <para>
9869 <firstterm>Aggregate functions</firstterm> compute a single result
9870 value from a set of input values. The built-in aggregate functions
9871 are listed in
9872 <xref linkend="functions-aggregate-table"> and
9873 <xref linkend="functions-aggregate-statistics-table">.
9874 The special syntax considerations for aggregate
9875 functions are explained in <xref linkend="syntax-aggregates">.
9876 Consult <xref linkend="tutorial-agg"> for additional introductory
9877 information.
9878 </para>
9880 <table id="functions-aggregate-table">
9881 <title>General-Purpose Aggregate Functions</title>
9883 <tgroup cols="4">
9884 <thead>
9885 <row>
9886 <entry>Function</entry>
9887 <entry>Argument Type</entry>
9888 <entry>Return Type</entry>
9889 <entry>Description</entry>
9890 </row>
9891 </thead>
9893 <tbody>
9894 <row>
9895 <entry>
9896 <indexterm>
9897 <primary>average</primary>
9898 </indexterm>
9899 <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
9900 </entry>
9901 <entry>
9902 <type>smallint</type>, <type>int</type>,
9903 <type>bigint</type>, <type>real</type>, <type>double
9904 precision</type>, <type>numeric</type>, or <type>interval</type>
9905 </entry>
9906 <entry>
9907 <type>numeric</type> for any integer type argument,
9908 <type>double precision</type> for a floating-point argument,
9909 otherwise the same as the argument data type
9910 </entry>
9911 <entry>the average (arithmetic mean) of all input values</entry>
9912 </row>
9914 <row>
9915 <entry>
9916 <indexterm>
9917 <primary>bit_and</primary>
9918 </indexterm>
9919 <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
9920 </entry>
9921 <entry>
9922 <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9923 <type>bit</type>
9924 </entry>
9925 <entry>
9926 same as argument data type
9927 </entry>
9928 <entry>the bitwise AND of all non-null input values, or null if none</entry>
9929 </row>
9931 <row>
9932 <entry>
9933 <indexterm>
9934 <primary>bit_or</primary>
9935 </indexterm>
9936 <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
9937 </entry>
9938 <entry>
9939 <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9940 <type>bit</type>
9941 </entry>
9942 <entry>
9943 same as argument data type
9944 </entry>
9945 <entry>the bitwise OR of all non-null input values, or null if none</entry>
9946 </row>
9948 <row>
9949 <entry>
9950 <indexterm>
9951 <primary>bool_and</primary>
9952 </indexterm>
9953 <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
9954 </entry>
9955 <entry>
9956 <type>bool</type>
9957 </entry>
9958 <entry>
9959 <type>bool</type>
9960 </entry>
9961 <entry>true if all input values are true, otherwise false</entry>
9962 </row>
9964 <row>
9965 <entry>
9966 <indexterm>
9967 <primary>bool_or</primary>
9968 </indexterm>
9969 <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
9970 </entry>
9971 <entry>
9972 <type>bool</type>
9973 </entry>
9974 <entry>
9975 <type>bool</type>
9976 </entry>
9977 <entry>true if at least one input value is true, otherwise false</entry>
9978 </row>
9980 <row>
9981 <entry><function>count(*)</function></entry>
9982 <entry></entry>
9983 <entry><type>bigint</type></entry>
9984 <entry>number of input rows</entry>
9985 </row>
9987 <row>
9988 <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
9989 <entry>any</entry>
9990 <entry><type>bigint</type></entry>
9991 <entry>
9992 number of input rows for which the value of <replaceable
9993 class="parameter">expression</replaceable> is not null
9994 </entry>
9995 </row>
9997 <row>
9998 <entry>
9999 <indexterm>
10000 <primary>every</primary>
10001 </indexterm>
10002 <function>every(<replaceable class="parameter">expression</replaceable>)</function>
10003 </entry>
10004 <entry>
10005 <type>bool</type>
10006 </entry>
10007 <entry>
10008 <type>bool</type>
10009 </entry>
10010 <entry>equivalent to <function>bool_and</function></entry>
10011 </row>
10013 <row>
10014 <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
10015 <entry>any array, numeric, string, or date/time type</entry>
10016 <entry>same as argument type</entry>
10017 <entry>
10018 maximum value of <replaceable
10019 class="parameter">expression</replaceable> across all input
10020 values
10021 </entry>
10022 </row>
10024 <row>
10025 <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
10026 <entry>any array, numeric, string, or date/time type</entry>
10027 <entry>same as argument type</entry>
10028 <entry>
10029 minimum value of <replaceable
10030 class="parameter">expression</replaceable> across all input
10031 values
10032 </entry>
10033 </row>
10035 <row>
10036 <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></entry>
10037 <entry>
10038 <type>smallint</type>, <type>int</type>,
10039 <type>bigint</type>, <type>real</type>, <type>double
10040 precision</type>, <type>numeric</type>, or
10041 <type>interval</type>
10042 </entry>
10043 <entry>
10044 <type>bigint</type> for <type>smallint</type> or
10045 <type>int</type> arguments, <type>numeric</type> for
10046 <type>bigint</type> arguments, <type>double precision</type>
10047 for floating-point arguments, otherwise the same as the
10048 argument data type
10049 </entry>
10050 <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
10051 </row>
10052 </tbody>
10053 </tgroup>
10054 </table>
10056 <para>
10057 It should be noted that except for <function>count</function>,
10058 these functions return a null value when no rows are selected. In
10059 particular, <function>sum</function> of no rows returns null, not
10060 zero as one might expect. The <function>coalesce</function> function can be
10061 used to substitute zero for null when necessary.
10062 </para>
10064 <note>
10065 <indexterm>
10066 <primary>ANY</primary>
10067 </indexterm>
10068 <indexterm>
10069 <primary>SOME</primary>
10070 </indexterm>
10071 <para>
10072 Boolean aggregates <function>bool_and</function> and
10073 <function>bool_or</function> correspond to standard SQL aggregates
10074 <function>every</function> and <function>any</function> or
10075 <function>some</function>.
10076 As for <function>any</function> and <function>some</function>,
10077 it seems that there is an ambiguity built into the standard syntax:
10078 <programlisting>
10079 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
10080 </programlisting>
10081 Here <function>ANY</function> can be considered both as leading
10082 to a subquery or as an aggregate if the select expression returns 1 row.
10083 Thus the standard name cannot be given to these aggregates.
10084 </para>
10085 </note>
10087 <note>
10088 <para>
10089 Users accustomed to working with other SQL database management
10090 systems might be surprised by the performance of the
10091 <function>count</function> aggregate when it is applied to the
10092 entire table. A query like:
10093 <programlisting>
10094 SELECT count(*) FROM sometable;
10095 </programlisting>
10096 will be executed by <productname>PostgreSQL</productname> using a
10097 sequential scan of the entire table.
10098 </para>
10099 </note>
10102 <para>
10103 <xref linkend="functions-aggregate-statistics-table"> shows
10104 aggregate functions typically used in statistical analysis.
10105 (These are separated out merely to avoid cluttering the listing
10106 of more-commonly-used aggregates.) Where the description mentions
10107 <replaceable class="parameter">N</replaceable>, it means the
10108 number of input rows for which all the input expressions are non-null.
10109 In all cases, null is returned if the computation is meaningless,
10110 for example when <replaceable class="parameter">N</replaceable> is zero.
10111 </para>
10113 <indexterm>
10114 <primary>statistics</primary>
10115 </indexterm>
10116 <indexterm>
10117 <primary>linear regression</primary>
10118 </indexterm>
10120 <table id="functions-aggregate-statistics-table">
10121 <title>Aggregate Functions for Statistics</title>
10123 <tgroup cols="4">
10124 <thead>
10125 <row>
10126 <entry>Function</entry>
10127 <entry>Argument Type</entry>
10128 <entry>Return Type</entry>
10129 <entry>Description</entry>
10130 </row>
10131 </thead>
10133 <tbody>
10135 <row>
10136 <entry>
10137 <indexterm>
10138 <primary>correlation</primary>
10139 </indexterm>
10140 <function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10141 </entry>
10142 <entry>
10143 <type>double precision</type>
10144 </entry>
10145 <entry>
10146 <type>double precision</type>
10147 </entry>
10148 <entry>correlation coefficient</entry>
10149 </row>
10151 <row>
10152 <entry>
10153 <indexterm>
10154 <primary>covariance</primary>
10155 <secondary>population</secondary>
10156 </indexterm>
10157 <function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10158 </entry>
10159 <entry>
10160 <type>double precision</type>
10161 </entry>
10162 <entry>
10163 <type>double precision</type>
10164 </entry>
10165 <entry>population covariance</entry>
10166 </row>
10168 <row>
10169 <entry>
10170 <indexterm>
10171 <primary>covariance</primary>
10172 <secondary>sample</secondary>
10173 </indexterm>
10174 <function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10175 </entry>
10176 <entry>
10177 <type>double precision</type>
10178 </entry>
10179 <entry>
10180 <type>double precision</type>
10181 </entry>
10182 <entry>sample covariance</entry>
10183 </row>
10185 <row>
10186 <entry>
10187 <function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10188 </entry>
10189 <entry>
10190 <type>double precision</type>
10191 </entry>
10192 <entry>
10193 <type>double precision</type>
10194 </entry>
10195 <entry>average of the independent variable
10196 (<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
10197 </row>
10199 <row>
10200 <entry>
10201 <function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10202 </entry>
10203 <entry>
10204 <type>double precision</type>
10205 </entry>
10206 <entry>
10207 <type>double precision</type>
10208 </entry>
10209 <entry>average of the dependent variable
10210 (<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
10211 </row>
10213 <row>
10214 <entry>
10215 <function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10216 </entry>
10217 <entry>
10218 <type>double precision</type>
10219 </entry>
10220 <entry>
10221 <type>bigint</type>
10222 </entry>
10223 <entry>number of input rows in which both expressions are nonnull</entry>
10224 </row>
10226 <row>
10227 <entry>
10228 <indexterm>
10229 <primary>regression intercept</primary>
10230 </indexterm>
10231 <function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10232 </entry>
10233 <entry>
10234 <type>double precision</type>
10235 </entry>
10236 <entry>
10237 <type>double precision</type>
10238 </entry>
10239 <entry>y-intercept of the least-squares-fit linear equation
10240 determined by the (<replaceable
10241 class="parameter">X</replaceable>, <replaceable
10242 class="parameter">Y</replaceable>) pairs</entry>
10243 </row>
10245 <row>
10246 <entry>
10247 <function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10248 </entry>
10249 <entry>
10250 <type>double precision</type>
10251 </entry>
10252 <entry>
10253 <type>double precision</type>
10254 </entry>
10255 <entry>square of the correlation coefficient</entry>
10256 </row>
10258 <row>
10259 <entry>
10260 <indexterm>
10261 <primary>regression slope</primary>
10262 </indexterm>
10263 <function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10264 </entry>
10265 <entry>
10266 <type>double precision</type>
10267 </entry>
10268 <entry>
10269 <type>double precision</type>
10270 </entry>
10271 <entry>slope of the least-squares-fit linear equation determined
10272 by the (<replaceable class="parameter">X</replaceable>,
10273 <replaceable class="parameter">Y</replaceable>) pairs</entry>
10274 </row>
10276 <row>
10277 <entry>
10278 <function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10279 </entry>
10280 <entry>
10281 <type>double precision</type>
10282 </entry>
10283 <entry>
10284 <type>double precision</type>
10285 </entry>
10286 <entry><literal>sum(<replaceable
10287 class="parameter">X</replaceable>^2) - sum(<replaceable
10288 class="parameter">X</replaceable>)^2/<replaceable
10289 class="parameter">N</replaceable></literal> (<quote>sum of
10290 squares</quote> of the independent variable)</entry>
10291 </row>
10293 <row>
10294 <entry>
10295 <function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10296 </entry>
10297 <entry>
10298 <type>double precision</type>
10299 </entry>
10300 <entry>
10301 <type>double precision</type>
10302 </entry>
10303 <entry><literal>sum(<replaceable
10304 class="parameter">X</replaceable>*<replaceable
10305 class="parameter">Y</replaceable>) - sum(<replaceable
10306 class="parameter">X</replaceable>) * sum(<replaceable
10307 class="parameter">Y</replaceable>)/<replaceable
10308 class="parameter">N</replaceable></literal> (<quote>sum of
10309 products</quote> of independent times dependent
10310 variable)</entry>
10311 </row>
10313 <row>
10314 <entry>
10315 <function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
10316 </entry>
10317 <entry>
10318 <type>double precision</type>
10319 </entry>
10320 <entry>
10321 <type>double precision</type>
10322 </entry>
10323 <entry><literal>sum(<replaceable
10324 class="parameter">Y</replaceable>^2) - sum(<replaceable
10325 class="parameter">Y</replaceable>)^2/<replaceable
10326 class="parameter">N</replaceable></literal> (<quote>sum of
10327 squares</quote> of the dependent variable)</entry>
10328 </row>
10330 <row>
10331 <entry>
10332 <indexterm>
10333 <primary>standard deviation</primary>
10334 </indexterm>
10335 <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
10336 </entry>
10337 <entry>
10338 <type>smallint</type>, <type>int</type>,
10339 <type>bigint</type>, <type>real</type>, <type>double
10340 precision</type>, or <type>numeric</type>
10341 </entry>
10342 <entry>
10343 <type>double precision</type> for floating-point arguments,
10344 otherwise <type>numeric</type>
10345 </entry>
10346 <entry>historical alias for <function>stddev_samp</function></entry>
10347 </row>
10349 <row>
10350 <entry>
10351 <indexterm>
10352 <primary>standard deviation</primary>
10353 <secondary>population</secondary>
10354 </indexterm>
10355 <function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
10356 </entry>
10357 <entry>
10358 <type>smallint</type>, <type>int</type>,
10359 <type>bigint</type>, <type>real</type>, <type>double
10360 precision</type>, or <type>numeric</type>
10361 </entry>
10362 <entry>
10363 <type>double precision</type> for floating-point arguments,
10364 otherwise <type>numeric</type>
10365 </entry>
10366 <entry>population standard deviation of the input values</entry>
10367 </row>
10369 <row>
10370 <entry>
10371 <indexterm>
10372 <primary>standard deviation</primary>
10373 <secondary>sample</secondary>
10374 </indexterm>
10375 <function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
10376 </entry>
10377 <entry>
10378 <type>smallint</type>, <type>int</type>,
10379 <type>bigint</type>, <type>real</type>, <type>double
10380 precision</type>, or <type>numeric</type>
10381 </entry>
10382 <entry>
10383 <type>double precision</type> for floating-point arguments,
10384 otherwise <type>numeric</type>
10385 </entry>
10386 <entry>sample standard deviation of the input values</entry>
10387 </row>
10389 <row>
10390 <entry>
10391 <indexterm>
10392 <primary>variance</primary>
10393 </indexterm>
10394 <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
10395 </entry>
10396 <entry>
10397 <type>smallint</type>, <type>int</type>,
10398 <type>bigint</type>, <type>real</type>, <type>double
10399 precision</type>, or <type>numeric</type>
10400 </entry>
10401 <entry>
10402 <type>double precision</type> for floating-point arguments,
10403 otherwise <type>numeric</type>
10404 </entry>
10405 <entry>historical alias for <function>var_samp</function></entry>
10406 </row>
10408 <row>
10409 <entry>
10410 <indexterm>
10411 <primary>variance</primary>
10412 <secondary>population</secondary>
10413 </indexterm>
10414 <function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
10415 </entry>
10416 <entry>
10417 <type>smallint</type>, <type>int</type>,
10418 <type>bigint</type>, <type>real</type>, <type>double
10419 precision</type>, or <type>numeric</type>
10420 </entry>
10421 <entry>
10422 <type>double precision</type> for floating-point arguments,
10423 otherwise <type>numeric</type>
10424 </entry>
10425 <entry>population variance of the input values (square of the population standard deviation)</entry>
10426 </row>
10428 <row>
10429 <entry>
10430 <indexterm>
10431 <primary>variance</primary>
10432 <secondary>sample</secondary>
10433 </indexterm>
10434 <function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
10435 </entry>
10436 <entry>
10437 <type>smallint</type>, <type>int</type>,
10438 <type>bigint</type>, <type>real</type>, <type>double
10439 precision</type>, or <type>numeric</type>
10440 </entry>
10441 <entry>
10442 <type>double precision</type> for floating-point arguments,
10443 otherwise <type>numeric</type>
10444 </entry>
10445 <entry>sample variance of the input values (square of the sample standard deviation)</entry>
10446 </row>
10447 </tbody>
10448 </tgroup>
10449 </table>
10451 </sect1>
10454 <sect1 id="functions-subquery">
10455 <title>Subquery Expressions</title>
10457 <indexterm>
10458 <primary>EXISTS</primary>
10459 </indexterm>
10461 <indexterm>
10462 <primary>IN</primary>
10463 </indexterm>
10465 <indexterm>
10466 <primary>NOT IN</primary>
10467 </indexterm>
10469 <indexterm>
10470 <primary>ANY</primary>
10471 </indexterm>
10473 <indexterm>
10474 <primary>ALL</primary>
10475 </indexterm>
10477 <indexterm>
10478 <primary>SOME</primary>
10479 </indexterm>
10481 <indexterm>
10482 <primary>subquery</primary>
10483 </indexterm>
10485 <para>
10486 This section describes the <acronym>SQL</acronym>-compliant subquery
10487 expressions available in <productname>PostgreSQL</productname>.
10488 All of the expression forms documented in this section return
10489 Boolean (true/false) results.
10490 </para>
10492 <sect2>
10493 <title><literal>EXISTS</literal></title>
10495 <synopsis>
10496 EXISTS (<replaceable>subquery</replaceable>)
10497 </synopsis>
10499 <para>
10500 The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
10501 or <firstterm>subquery</firstterm>. The
10502 subquery is evaluated to determine whether it returns any rows.
10503 If it returns at least one row, the result of <token>EXISTS</token> is
10504 <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
10505 is <quote>false</>.
10506 </para>
10508 <para>
10509 The subquery can refer to variables from the surrounding query,
10510 which will act as constants during any one evaluation of the subquery.
10511 </para>
10513 <para>
10514 The subquery will generally only be executed far enough to determine
10515 whether at least one row is returned, not all the way to completion.
10516 It is unwise to write a subquery that has any side effects (such as
10517 calling sequence functions); whether the side effects occur or not
10518 might be difficult to predict.
10519 </para>
10521 <para>
10522 Since the result depends only on whether any rows are returned,
10523 and not on the contents of those rows, the output list of the
10524 subquery is normally uninteresting. A common coding convention is
10525 to write all <literal>EXISTS</> tests in the form
10526 <literal>EXISTS(SELECT 1 WHERE ...)</literal>. There are exceptions to
10527 this rule however, such as subqueries that use <token>INTERSECT</token>.
10528 </para>
10530 <para>
10531 This simple example is like an inner join on <literal>col2</>, but
10532 it produces at most one output row for each <literal>tab1</> row,
10533 even if there are multiple matching <literal>tab2</> rows:
10534 <screen>
10535 SELECT col1 FROM tab1
10536 WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
10537 </screen>
10538 </para>
10539 </sect2>
10541 <sect2>
10542 <title><literal>IN</literal></title>
10544 <synopsis>
10545 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
10546 </synopsis>
10548 <para>
10549 The right-hand side is a parenthesized
10550 subquery, which must return exactly one column. The left-hand expression
10551 is evaluated and compared to each row of the subquery result.
10552 The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10553 The result is <quote>false</> if no equal row is found (including the special
10554 case where the subquery returns no rows).
10555 </para>
10557 <para>
10558 Note that if the left-hand expression yields null, or if there are
10559 no equal right-hand values and at least one right-hand row yields
10560 null, the result of the <token>IN</token> construct will be null, not false.
10561 This is in accordance with SQL's normal rules for Boolean combinations
10562 of null values.
10563 </para>
10565 <para>
10566 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10567 be evaluated completely.
10568 </para>
10570 <synopsis>
10571 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
10572 </synopsis>
10574 <para>
10575 The left-hand side of this form of <token>IN</token> is a row constructor,
10576 as described in <xref linkend="sql-syntax-row-constructors">.
10577 The right-hand side is a parenthesized
10578 subquery, which must return exactly as many columns as there are
10579 expressions in the left-hand row. The left-hand expressions are
10580 evaluated and compared row-wise to each row of the subquery result.
10581 The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10582 The result is <quote>false</> if no equal row is found (including the special
10583 case where the subquery returns no rows).
10584 </para>
10586 <para>
10587 As usual, null values in the rows are combined per
10588 the normal rules of SQL Boolean expressions. Two rows are considered
10589 equal if all their corresponding members are non-null and equal; the rows
10590 are unequal if any corresponding members are non-null and unequal;
10591 otherwise the result of that row comparison is unknown (null).
10592 If all the per-row results are either unequal or null, with at least one
10593 null, then the result of <token>IN</token> is null.
10594 </para>
10595 </sect2>
10597 <sect2>
10598 <title><literal>NOT IN</literal></title>
10600 <synopsis>
10601 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10602 </synopsis>
10604 <para>
10605 The right-hand side is a parenthesized
10606 subquery, which must return exactly one column. The left-hand expression
10607 is evaluated and compared to each row of the subquery result.
10608 The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10609 are found (including the special case where the subquery returns no rows).
10610 The result is <quote>false</> if any equal row is found.
10611 </para>
10613 <para>
10614 Note that if the left-hand expression yields null, or if there are
10615 no equal right-hand values and at least one right-hand row yields
10616 null, the result of the <token>NOT IN</token> construct will be null, not true.
10617 This is in accordance with SQL's normal rules for Boolean combinations
10618 of null values.
10619 </para>
10621 <para>
10622 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10623 be evaluated completely.
10624 </para>
10626 <synopsis>
10627 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10628 </synopsis>
10630 <para>
10631 The left-hand side of this form of <token>NOT IN</token> is a row constructor,
10632 as described in <xref linkend="sql-syntax-row-constructors">.
10633 The right-hand side is a parenthesized
10634 subquery, which must return exactly as many columns as there are
10635 expressions in the left-hand row. The left-hand expressions are
10636 evaluated and compared row-wise to each row of the subquery result.
10637 The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10638 are found (including the special case where the subquery returns no rows).
10639 The result is <quote>false</> if any equal row is found.
10640 </para>
10642 <para>
10643 As usual, null values in the rows are combined per
10644 the normal rules of SQL Boolean expressions. Two rows are considered
10645 equal if all their corresponding members are non-null and equal; the rows
10646 are unequal if any corresponding members are non-null and unequal;
10647 otherwise the result of that row comparison is unknown (null).
10648 If all the per-row results are either unequal or null, with at least one
10649 null, then the result of <token>NOT IN</token> is null.
10650 </para>
10651 </sect2>
10653 <sect2>
10654 <title><literal>ANY</literal>/<literal>SOME</literal></title>
10656 <synopsis>
10657 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
10658 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
10659 </synopsis>
10661 <para>
10662 The right-hand side is a parenthesized
10663 subquery, which must return exactly one column. The left-hand expression
10664 is evaluated and compared to each row of the subquery result using the
10665 given <replaceable>operator</replaceable>, which must yield a Boolean
10666 result.
10667 The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10668 The result is <quote>false</> if no true result is found (including the special
10669 case where the subquery returns no rows).
10670 </para>
10672 <para>
10673 <token>SOME</token> is a synonym for <token>ANY</token>.
10674 <token>IN</token> is equivalent to <literal>= ANY</literal>.
10675 </para>
10677 <para>
10678 Note that if there are no successes and at least one right-hand row yields
10679 null for the operator's result, the result of the <token>ANY</token> construct
10680 will be null, not false.
10681 This is in accordance with SQL's normal rules for Boolean combinations
10682 of null values.
10683 </para>
10685 <para>
10686 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10687 be evaluated completely.
10688 </para>
10690 <synopsis>
10691 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
10692 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
10693 </synopsis>
10695 <para>
10696 The left-hand side of this form of <token>ANY</token> is a row constructor,
10697 as described in <xref linkend="sql-syntax-row-constructors">.
10698 The right-hand side is a parenthesized
10699 subquery, which must return exactly as many columns as there are
10700 expressions in the left-hand row. The left-hand expressions are
10701 evaluated and compared row-wise to each row of the subquery result,
10702 using the given <replaceable>operator</replaceable>.
10703 The result of <token>ANY</token> is <quote>true</> if the comparison
10704 returns true for any subquery row.
10705 The result is <quote>false</> if the comparison returns false for every
10706 subquery row (including the special case where the subquery returns no
10707 rows).
10708 The result is NULL if the comparison does not return true for any row,
10709 and it returns NULL for at least one row.
10710 </para>
10712 <para>
10713 See <xref linkend="row-wise-comparison"> for details about the meaning
10714 of a row-wise comparison.
10715 </para>
10716 </sect2>
10718 <sect2>
10719 <title><literal>ALL</literal></title>
10721 <synopsis>
10722 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10723 </synopsis>
10725 <para>
10726 The right-hand side is a parenthesized
10727 subquery, which must return exactly one column. The left-hand expression
10728 is evaluated and compared to each row of the subquery result using the
10729 given <replaceable>operator</replaceable>, which must yield a Boolean
10730 result.
10731 The result of <token>ALL</token> is <quote>true</> if all rows yield true
10732 (including the special case where the subquery returns no rows).
10733 The result is <quote>false</> if any false result is found.
10734 The result is NULL if the comparison does not return false for any row,
10735 and it returns NULL for at least one row.
10736 </para>
10738 <para>
10739 <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
10740 </para>
10742 <para>
10743 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10744 be evaluated completely.
10745 </para>
10747 <synopsis>
10748 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10749 </synopsis>
10751 <para>
10752 The left-hand side of this form of <token>ALL</token> is a row constructor,
10753 as described in <xref linkend="sql-syntax-row-constructors">.
10754 The right-hand side is a parenthesized
10755 subquery, which must return exactly as many columns as there are
10756 expressions in the left-hand row. The left-hand expressions are
10757 evaluated and compared row-wise to each row of the subquery result,
10758 using the given <replaceable>operator</replaceable>.
10759 The result of <token>ALL</token> is <quote>true</> if the comparison
10760 returns true for all subquery rows (including the special
10761 case where the subquery returns no rows).
10762 The result is <quote>false</> if the comparison returns false for any
10763 subquery row.
10764 The result is NULL if the comparison does not return false for any
10765 subquery row, and it returns NULL for at least one row.
10766 </para>
10768 <para>
10769 See <xref linkend="row-wise-comparison"> for details about the meaning
10770 of a row-wise comparison.
10771 </para>
10772 </sect2>
10774 <sect2>
10775 <title>Row-wise Comparison</title>
10777 <indexterm zone="functions-subquery">
10778 <primary>comparison</primary>
10779 <secondary>subquery result row</secondary>
10780 </indexterm>
10782 <synopsis>
10783 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
10784 </synopsis>
10786 <para>
10787 The left-hand side is a row constructor,
10788 as described in <xref linkend="sql-syntax-row-constructors">.
10789 The right-hand side is a parenthesized subquery, which must return exactly
10790 as many columns as there are expressions in the left-hand row. Furthermore,
10791 the subquery cannot return more than one row. (If it returns zero rows,
10792 the result is taken to be null.) The left-hand side is evaluated and
10793 compared row-wise to the single subquery result row.
10794 </para>
10796 <para>
10797 See <xref linkend="row-wise-comparison"> for details about the meaning
10798 of a row-wise comparison.
10799 </para>
10800 </sect2>
10801 </sect1>
10804 <sect1 id="functions-comparisons">
10805 <title>Row and Array Comparisons</title>
10807 <indexterm>
10808 <primary>IN</primary>
10809 </indexterm>
10811 <indexterm>
10812 <primary>NOT IN</primary>
10813 </indexterm>
10815 <indexterm>
10816 <primary>ANY</primary>
10817 </indexterm>
10819 <indexterm>
10820 <primary>ALL</primary>
10821 </indexterm>
10823 <indexterm>
10824 <primary>SOME</primary>
10825 </indexterm>
10827 <indexterm>
10828 <primary>row-wise comparison</primary>
10829 </indexterm>
10831 <indexterm>
10832 <primary>comparison</primary>
10833 <secondary>row-wise</secondary>
10834 </indexterm>
10836 <indexterm>
10837 <primary>IS DISTINCT FROM</primary>
10838 </indexterm>
10840 <indexterm>
10841 <primary>IS NOT DISTINCT FROM</primary>
10842 </indexterm>
10844 <para>
10845 This section describes several specialized constructs for making
10846 multiple comparisons between groups of values. These forms are
10847 syntactically related to the subquery forms of the previous section,
10848 but do not involve subqueries.
10849 The forms involving array subexpressions are
10850 <productname>PostgreSQL</productname> extensions; the rest are
10851 <acronym>SQL</acronym>-compliant.
10852 All of the expression forms documented in this section return
10853 Boolean (true/false) results.
10854 </para>
10856 <sect2>
10857 <title><literal>IN</literal></title>
10859 <synopsis>
10860 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10861 </synopsis>
10863 <para>
10864 The right-hand side is a parenthesized list
10865 of scalar expressions. The result is <quote>true</> if the left-hand expression's
10866 result is equal to any of the right-hand expressions. This is a shorthand
10867 notation for
10869 <synopsis>
10870 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
10872 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
10875 </synopsis>
10876 </para>
10878 <para>
10879 Note that if the left-hand expression yields null, or if there are
10880 no equal right-hand values and at least one right-hand expression yields
10881 null, the result of the <token>IN</token> construct will be null, not false.
10882 This is in accordance with SQL's normal rules for Boolean combinations
10883 of null values.
10884 </para>
10885 </sect2>
10887 <sect2>
10888 <title><literal>NOT IN</literal></title>
10890 <synopsis>
10891 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10892 </synopsis>
10894 <para>
10895 The right-hand side is a parenthesized list
10896 of scalar expressions. The result is <quote>true</quote> if the left-hand expression's
10897 result is unequal to all of the right-hand expressions. This is a shorthand
10898 notation for
10900 <synopsis>
10901 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
10903 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
10906 </synopsis>
10907 </para>
10909 <para>
10910 Note that if the left-hand expression yields null, or if there are
10911 no equal right-hand values and at least one right-hand expression yields
10912 null, the result of the <token>NOT IN</token> construct will be null, not true
10913 as one might naively expect.
10914 This is in accordance with SQL's normal rules for Boolean combinations
10915 of null values.
10916 </para>
10918 <tip>
10919 <para>
10920 <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
10921 cases. However, null values are much more likely to trip up the novice when
10922 working with <token>NOT IN</token> than when working with <token>IN</token>.
10923 It's best to express your condition positively if possible.
10924 </para>
10925 </tip>
10926 </sect2>
10928 <sect2>
10929 <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
10931 <synopsis>
10932 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
10933 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
10934 </synopsis>
10936 <para>
10937 The right-hand side is a parenthesized expression, which must yield an
10938 array value.
10939 The left-hand expression
10940 is evaluated and compared to each element of the array using the
10941 given <replaceable>operator</replaceable>, which must yield a Boolean
10942 result.
10943 The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10944 The result is <quote>false</> if no true result is found (including the special
10945 case where the array has zero elements).
10946 </para>
10948 <para>
10949 If the array expression yields a null array, the result of
10950 <token>ANY</token> will be null. If the left-hand expression yields null,
10951 the result of <token>ANY</token> is ordinarily null (though a non-strict
10952 comparison operator could possibly yield a different result).
10953 Also, if the right-hand array contains any null elements and no true
10954 comparison result is obtained, the result of <token>ANY</token>
10955 will be null, not false (again, assuming a strict comparison operator).
10956 This is in accordance with SQL's normal rules for Boolean combinations
10957 of null values.
10958 </para>
10960 <para>
10961 <token>SOME</token> is a synonym for <token>ANY</token>.
10962 </para>
10963 </sect2>
10965 <sect2>
10966 <title><literal>ALL</literal> (array)</title>
10968 <synopsis>
10969 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
10970 </synopsis>
10972 <para>
10973 The right-hand side is a parenthesized expression, which must yield an
10974 array value.
10975 The left-hand expression
10976 is evaluated and compared to each element of the array using the
10977 given <replaceable>operator</replaceable>, which must yield a Boolean
10978 result.
10979 The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
10980 (including the special case where the array has zero elements).
10981 The result is <quote>false</> if any false result is found.
10982 </para>
10984 <para>
10985 If the array expression yields a null array, the result of
10986 <token>ALL</token> will be null. If the left-hand expression yields null,
10987 the result of <token>ALL</token> is ordinarily null (though a non-strict
10988 comparison operator could possibly yield a different result).
10989 Also, if the right-hand array contains any null elements and no false
10990 comparison result is obtained, the result of <token>ALL</token>
10991 will be null, not true (again, assuming a strict comparison operator).
10992 This is in accordance with SQL's normal rules for Boolean combinations
10993 of null values.
10994 </para>
10995 </sect2>
10997 <sect2 id="row-wise-comparison">
10998 <title>Row-wise Comparison</title>
11000 <synopsis>
11001 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
11002 </synopsis>
11004 <para>
11005 Each side is a row constructor,
11006 as described in <xref linkend="sql-syntax-row-constructors">.
11007 The two row values must have the same number of fields.
11008 Each side is evaluated and they are compared row-wise. Row comparisons
11009 are allowed when the <replaceable>operator</replaceable> is
11010 <literal>=</>,
11011 <literal>&lt;&gt;</>,
11012 <literal>&lt;</>,
11013 <literal>&lt;=</>,
11014 <literal>&gt;</> or
11015 <literal>&gt;=</>,
11016 or has semantics similar to one of these. (To be specific, an operator
11017 can be a row comparison operator if it is a member of a B-Tree operator
11018 class, or is the negator of the <literal>=</> member of a B-Tree operator
11019 class.)
11020 </para>
11022 <para>
11023 The <literal>=</> and <literal>&lt;&gt;</> cases work slightly differently
11024 from the others. Two rows are considered
11025 equal if all their corresponding members are non-null and equal; the rows
11026 are unequal if any corresponding members are non-null and unequal;
11027 otherwise the result of the row comparison is unknown (null).
11028 </para>
11030 <para>
11031 For the <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and
11032 <literal>&gt;=</> cases, the row elements are compared left-to-right,
11033 stopping as soon as an unequal or null pair of elements is found.
11034 If either of this pair of elements is null, the result of the
11035 row comparison is unknown (null); otherwise comparison of this pair
11036 of elements determines the result. For example,
11037 <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</>
11038 yields true, not null, because the third pair of elements are not
11039 considered.
11040 </para>
11042 <note>
11043 <para>
11044 Prior to <productname>PostgreSQL</productname> 8.2, the
11045 <literal>&lt;</>, <literal>&lt;=</>, <literal>&gt;</> and <literal>&gt;=</>
11046 cases were not handled per SQL specification. A comparison like
11047 <literal>ROW(a,b) &lt; ROW(c,d)</>
11048 was implemented as
11049 <literal>a &lt; c AND b &lt; d</>
11050 whereas the correct behavior is equivalent to
11051 <literal>a &lt; c OR (a = c AND b &lt; d)</>.
11052 </para>
11053 </note>
11055 <synopsis>
11056 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
11057 </synopsis>
11059 <para>
11060 This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
11061 but it does not yield null for null inputs. Instead, any null value is
11062 considered unequal to (distinct from) any non-null value, and any two
11063 nulls are considered equal (not distinct). Thus the result will always
11064 be either true or false, never null.
11065 </para>
11067 <synopsis>
11068 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
11069 </synopsis>
11071 <para>
11072 This construct is similar to a <literal>=</literal> row comparison,
11073 but it does not yield null for null inputs. Instead, any null value is
11074 considered unequal to (distinct from) any non-null value, and any two
11075 nulls are considered equal (not distinct). Thus the result will always
11076 be either true or false, never null.
11077 </para>
11079 </sect2>
11080 </sect1>
11082 <sect1 id="functions-srf">
11083 <title>Set Returning Functions</title>
11085 <indexterm zone="functions-srf">
11086 <primary>set returning functions</primary>
11087 <secondary>functions</secondary>
11088 </indexterm>
11090 <indexterm>
11091 <primary>generate_series</primary>
11092 </indexterm>
11094 <para>
11095 This section describes functions that possibly return more than one row.
11096 Currently the only functions in this class are series generating functions,
11097 as detailed in <xref linkend="functions-srf-series">.
11098 </para>
11100 <table id="functions-srf-series">
11101 <title>Series Generating Functions</title>
11102 <tgroup cols="4">
11103 <thead>
11104 <row>
11105 <entry>Function</entry>
11106 <entry>Argument Type</entry>
11107 <entry>Return Type</entry>
11108 <entry>Description</entry>
11109 </row>
11110 </thead>
11112 <tbody>
11113 <row>
11114 <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>)</literal></entry>
11115 <entry><type>int</type> or <type>bigint</type></entry>
11116 <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
11117 <entry>
11118 Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11119 with a step size of one
11120 </entry>
11121 </row>
11123 <row>
11124 <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</literal></entry>
11125 <entry><type>int</type> or <type>bigint</type></entry>
11126 <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
11127 <entry>
11128 Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11129 with a step size of <parameter>step</parameter>
11130 </entry>
11131 </row>
11133 </tbody>
11134 </tgroup>
11135 </table>
11137 <para>
11138 When <parameter>step</parameter> is positive, zero rows are returned if
11139 <parameter>start</parameter> is greater than <parameter>stop</parameter>.
11140 Conversely, when <parameter>step</parameter> is negative, zero rows are
11141 returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
11142 Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
11143 for <parameter>step</parameter> to be zero. Some examples follow:
11144 <programlisting>
11145 select * from generate_series(2,4);
11146 generate_series
11147 -----------------
11151 (3 rows)
11153 select * from generate_series(5,1,-2);
11154 generate_series
11155 -----------------
11159 (3 rows)
11161 select * from generate_series(4,3);
11162 generate_series
11163 -----------------
11164 (0 rows)
11166 select current_date + s.a as dates from generate_series(0,14,7) as s(a);
11167 dates
11168 ------------
11169 2004-02-05
11170 2004-02-12
11171 2004-02-19
11172 (3 rows)
11173 </programlisting>
11174 </para>
11175 </sect1>
11177 <sect1 id="functions-info">
11178 <title>System Information Functions</title>
11180 <para>
11181 <xref linkend="functions-info-session-table"> shows several
11182 functions that extract session and system information.
11183 </para>
11185 <para>
11186 In addition to the functions listed in this section, there are a number of
11187 functions related to the statistics system that also provide system
11188 information. See <xref linkend="monitoring-stats-views"> for more
11189 information.
11190 </para>
11192 <table id="functions-info-session-table">
11193 <title>Session Information Functions</title>
11194 <tgroup cols="3">
11195 <thead>
11196 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11197 </thead>
11199 <tbody>
11200 <row>
11201 <entry><literal><function>current_database</function>()</literal></entry>
11202 <entry><type>name</type></entry>
11203 <entry>name of current database</entry>
11204 </row>
11206 <row>
11207 <entry><literal><function>current_schema</function>()</literal></entry>
11208 <entry><type>name</type></entry>
11209 <entry>name of current schema</entry>
11210 </row>
11212 <row>
11213 <entry><literal><function>current_schemas</function>(<type>boolean</type>)</literal></entry>
11214 <entry><type>name[]</type></entry>
11215 <entry>names of schemas in search path optionally including implicit schemas</entry>
11216 </row>
11218 <row>
11219 <entry><literal><function>current_user</function></literal></entry>
11220 <entry><type>name</type></entry>
11221 <entry>user name of current execution context</entry>
11222 </row>
11224 <row>
11225 <entry><literal><function>inet_client_addr</function>()</literal></entry>
11226 <entry><type>inet</type></entry>
11227 <entry>address of the remote connection</entry>
11228 </row>
11230 <row>
11231 <entry><literal><function>inet_client_port</function>()</literal></entry>
11232 <entry><type>int</type></entry>
11233 <entry>port of the remote connection</entry>
11234 </row>
11236 <row>
11237 <entry><literal><function>inet_server_addr</function>()</literal></entry>
11238 <entry><type>inet</type></entry>
11239 <entry>address of the local connection</entry>
11240 </row>
11242 <row>
11243 <entry><literal><function>inet_server_port</function>()</literal></entry>
11244 <entry><type>int</type></entry>
11245 <entry>port of the local connection</entry>
11246 </row>
11248 <row>
11249 <entry><literal><function>pg_my_temp_schema</function>()</literal></entry>
11250 <entry><type>oid</type></entry>
11251 <entry>OID of session's temporary schema, or 0 if none</entry>
11252 </row>
11254 <row>
11255 <entry><literal><function>pg_is_other_temp_schema</function>(<type>oid</type>)</literal></entry>
11256 <entry><type>boolean</type></entry>
11257 <entry>is schema another session's temporary schema?</entry>
11258 </row>
11260 <row>
11261 <entry><literal><function>pg_postmaster_start_time</function>()</literal></entry>
11262 <entry><type>timestamp with time zone</type></entry>
11263 <entry>server start time</entry>
11264 </row>
11266 <row>
11267 <entry><literal><function>session_user</function></literal></entry>
11268 <entry><type>name</type></entry>
11269 <entry>session user name</entry>
11270 </row>
11272 <row>
11273 <entry><literal><function>user</function></literal></entry>
11274 <entry><type>name</type></entry>
11275 <entry>equivalent to <function>current_user</function></entry>
11276 </row>
11278 <row>
11279 <entry><literal><function>version</function>()</literal></entry>
11280 <entry><type>text</type></entry>
11281 <entry><productname>PostgreSQL</> version information</entry>
11282 </row>
11283 </tbody>
11284 </tgroup>
11285 </table>
11287 <indexterm>
11288 <primary>user</primary>
11289 <secondary>current</secondary>
11290 </indexterm>
11292 <indexterm>
11293 <primary>schema</primary>
11294 <secondary>current</secondary>
11295 </indexterm>
11297 <indexterm>
11298 <primary>search path</primary>
11299 <secondary>current</secondary>
11300 </indexterm>
11302 <para>
11303 The <function>session_user</function> is normally the user who initiated
11304 the current database connection; but superusers can change this setting
11305 with <xref linkend="sql-set-session-authorization" endterm="sql-set-session-authorization-title">.
11306 The <function>current_user</function> is the user identifier
11307 that is applicable for permission checking. Normally, it is equal
11308 to the session user, but it can be changed with
11309 <xref linkend="sql-set-role" endterm="sql-set-role-title">.
11310 It also changes during the execution of
11311 functions with the attribute <literal>SECURITY DEFINER</literal>.
11312 In Unix parlance, the session user is the <quote>real user</quote> and
11313 the current user is the <quote>effective user</quote>.
11314 </para>
11316 <note>
11317 <para>
11318 <function>current_user</function>, <function>session_user</function>, and
11319 <function>user</function> have special syntactic status in <acronym>SQL</acronym>:
11320 they must be called without trailing parentheses.
11321 </para>
11322 </note>
11324 <para>
11325 <function>current_schema</function> returns the name of the schema that is
11326 at the front of the search path (or a null value if the search path is
11327 empty). This is the schema that will be used for any tables or
11328 other named objects that are created without specifying a target schema.
11329 <function>current_schemas(boolean)</function> returns an array of the names of all
11330 schemas presently in the search path. The Boolean option determines whether or not
11331 implicitly included system schemas such as <literal>pg_catalog</> are included in the search
11332 path returned.
11333 </para>
11335 <note>
11336 <para>
11337 The search path can be altered at run time. The command is:
11338 <programlisting>
11339 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
11340 </programlisting>
11341 </para>
11342 </note>
11344 <indexterm>
11345 <primary>inet_client_addr</primary>
11346 </indexterm>
11348 <indexterm>
11349 <primary>inet_client_port</primary>
11350 </indexterm>
11352 <indexterm>
11353 <primary>inet_server_addr</primary>
11354 </indexterm>
11356 <indexterm>
11357 <primary>inet_server_port</primary>
11358 </indexterm>
11360 <para>
11361 <function>inet_client_addr</function> returns the IP address of the
11362 current client, and <function>inet_client_port</function> returns the
11363 port number.
11364 <function>inet_server_addr</function> returns the IP address on which
11365 the server accepted the current connection, and
11366 <function>inet_server_port</function> returns the port number.
11367 All these functions return NULL if the current connection is via a
11368 Unix-domain socket.
11369 </para>
11371 <indexterm>
11372 <primary>pg_my_temp_schema</primary>
11373 </indexterm>
11375 <indexterm>
11376 <primary>pg_is_other_temp_schema</primary>
11377 </indexterm>
11379 <para>
11380 <function>pg_my_temp_schema</function> returns the OID of the current
11381 session's temporary schema, or 0 if it has none (because it has not
11382 created any temporary tables).
11383 <function>pg_is_other_temp_schema</function> returns true if the
11384 given OID is the OID of any other session's temporary schema.
11385 (This can be useful, for example, to exclude other sessions' temporary
11386 tables from a catalog display.)
11387 </para>
11389 <indexterm>
11390 <primary>pg_postmaster_start_time</primary>
11391 </indexterm>
11393 <para>
11394 <function>pg_postmaster_start_time</function> returns the
11395 <type>timestamp with time zone</type> when the
11396 server started.
11397 </para>
11399 <indexterm>
11400 <primary>version</primary>
11401 </indexterm>
11403 <para>
11404 <function>version</function> returns a string describing the
11405 <productname>PostgreSQL</productname> server's version.
11406 </para>
11408 <indexterm>
11409 <primary>privilege</primary>
11410 <secondary>querying</secondary>
11411 </indexterm>
11413 <para>
11414 <xref linkend="functions-info-access-table"> lists functions that
11415 allow the user to query object access privileges programmatically.
11416 See <xref linkend="ddl-priv"> for more information about
11417 privileges.
11418 </para>
11420 <table id="functions-info-access-table">
11421 <title>Access Privilege Inquiry Functions</title>
11422 <tgroup cols="3">
11423 <thead>
11424 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11425 </thead>
11427 <tbody>
11428 <row>
11429 <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
11430 <parameter>database</parameter>,
11431 <parameter>privilege</parameter>)</literal>
11432 </entry>
11433 <entry><type>boolean</type></entry>
11434 <entry>does user have privilege for database</entry>
11435 </row>
11436 <row>
11437 <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
11438 <parameter>privilege</parameter>)</literal>
11439 </entry>
11440 <entry><type>boolean</type></entry>
11441 <entry>does current user have privilege for database</entry>
11442 </row>
11443 <row>
11444 <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
11445 <parameter>function</parameter>,
11446 <parameter>privilege</parameter>)</literal>
11447 </entry>
11448 <entry><type>boolean</type></entry>
11449 <entry>does user have privilege for function</entry>
11450 </row>
11451 <row>
11452 <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
11453 <parameter>privilege</parameter>)</literal>
11454 </entry>
11455 <entry><type>boolean</type></entry>
11456 <entry>does current user have privilege for function</entry>
11457 </row>
11458 <row>
11459 <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
11460 <parameter>language</parameter>,
11461 <parameter>privilege</parameter>)</literal>
11462 </entry>
11463 <entry><type>boolean</type></entry>
11464 <entry>does user have privilege for language</entry>
11465 </row>
11466 <row>
11467 <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
11468 <parameter>privilege</parameter>)</literal>
11469 </entry>
11470 <entry><type>boolean</type></entry>
11471 <entry>does current user have privilege for language</entry>
11472 </row>
11473 <row>
11474 <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
11475 <parameter>schema</parameter>,
11476 <parameter>privilege</parameter>)</literal>
11477 </entry>
11478 <entry><type>boolean</type></entry>
11479 <entry>does user have privilege for schema</entry>
11480 </row>
11481 <row>
11482 <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
11483 <parameter>privilege</parameter>)</literal>
11484 </entry>
11485 <entry><type>boolean</type></entry>
11486 <entry>does current user have privilege for schema</entry>
11487 </row>
11488 <row>
11489 <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
11490 <parameter>table</parameter>,
11491 <parameter>privilege</parameter>)</literal>
11492 </entry>
11493 <entry><type>boolean</type></entry>
11494 <entry>does user have privilege for table</entry>
11495 </row>
11496 <row>
11497 <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
11498 <parameter>privilege</parameter>)</literal>
11499 </entry>
11500 <entry><type>boolean</type></entry>
11501 <entry>does current user have privilege for table</entry>
11502 </row>
11503 <row>
11504 <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
11505 <parameter>tablespace</parameter>,
11506 <parameter>privilege</parameter>)</literal>
11507 </entry>
11508 <entry><type>boolean</type></entry>
11509 <entry>does user have privilege for tablespace</entry>
11510 </row>
11511 <row>
11512 <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
11513 <parameter>privilege</parameter>)</literal>
11514 </entry>
11515 <entry><type>boolean</type></entry>
11516 <entry>does current user have privilege for tablespace</entry>
11517 </row>
11518 <row>
11519 <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
11520 <parameter>role</parameter>,
11521 <parameter>privilege</parameter>)</literal>
11522 </entry>
11523 <entry><type>boolean</type></entry>
11524 <entry>does user have privilege for role</entry>
11525 </row>
11526 <row>
11527 <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
11528 <parameter>privilege</parameter>)</literal>
11529 </entry>
11530 <entry><type>boolean</type></entry>
11531 <entry>does current user have privilege for role</entry>
11532 </row>
11533 </tbody>
11534 </tgroup>
11535 </table>
11537 <indexterm>
11538 <primary>has_database_privilege</primary>
11539 </indexterm>
11540 <indexterm>
11541 <primary>has_function_privilege</primary>
11542 </indexterm>
11543 <indexterm>
11544 <primary>has_language_privilege</primary>
11545 </indexterm>
11546 <indexterm>
11547 <primary>has_schema_privilege</primary>
11548 </indexterm>
11549 <indexterm>
11550 <primary>has_table_privilege</primary>
11551 </indexterm>
11552 <indexterm>
11553 <primary>has_tablespace_privilege</primary>
11554 </indexterm>
11555 <indexterm>
11556 <primary>pg_has_role</primary>
11557 </indexterm>
11559 <para>
11560 <function>has_database_privilege</function> checks whether a user
11561 can access a database in a particular way. The possibilities for its
11562 arguments are analogous to <function>has_table_privilege</function>.
11563 The desired access privilege type must evaluate to
11564 <literal>CREATE</literal>,
11565 <literal>CONNECT</literal>,
11566 <literal>TEMPORARY</literal>, or
11567 <literal>TEMP</literal> (which is equivalent to
11568 <literal>TEMPORARY</literal>).
11569 </para>
11571 <para>
11572 <function>has_function_privilege</function> checks whether a user
11573 can access a function in a particular way. The possibilities for its
11574 arguments are analogous to <function>has_table_privilege</function>.
11575 When specifying a function by a text string rather than by OID,
11576 the allowed input is the same as for the <type>regprocedure</> data type
11577 (see <xref linkend="datatype-oid">).
11578 The desired access privilege type must evaluate to
11579 <literal>EXECUTE</literal>.
11580 An example is:
11581 <programlisting>
11582 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
11583 </programlisting>
11584 </para>
11586 <para>
11587 <function>has_language_privilege</function> checks whether a user
11588 can access a procedural language in a particular way. The possibilities
11589 for its arguments are analogous to <function>has_table_privilege</function>.
11590 The desired access privilege type must evaluate to
11591 <literal>USAGE</literal>.
11592 </para>
11594 <para>
11595 <function>has_schema_privilege</function> checks whether a user
11596 can access a schema in a particular way. The possibilities for its
11597 arguments are analogous to <function>has_table_privilege</function>.
11598 The desired access privilege type must evaluate to
11599 <literal>CREATE</literal> or
11600 <literal>USAGE</literal>.
11601 </para>
11603 <para>
11604 <function>has_table_privilege</function> checks whether a user
11605 can access a table in a particular way. The user can be
11606 specified by name or by OID
11607 (<literal>pg_authid.oid</literal>), or if the argument is
11608 omitted
11609 <function>current_user</function> is assumed. The table can be specified
11610 by name or by OID. (Thus, there are actually six variants of
11611 <function>has_table_privilege</function>, which can be distinguished by
11612 the number and types of their arguments.) When specifying by name,
11613 the name can be schema-qualified if necessary.
11614 The desired access privilege type
11615 is specified by a text string, which must evaluate to one of the
11616 values <literal>SELECT</literal>, <literal>INSERT</literal>,
11617 <literal>UPDATE</literal>, <literal>DELETE</literal>,
11618 <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>.
11619 (Case of the string is not significant, however.)
11620 An example is:
11621 <programlisting>
11622 SELECT has_table_privilege('myschema.mytable', 'select');
11623 </programlisting>
11624 </para>
11626 <para>
11627 <function>has_tablespace_privilege</function> checks whether a user
11628 can access a tablespace in a particular way. The possibilities for its
11629 arguments are analogous to <function>has_table_privilege</function>.
11630 The desired access privilege type must evaluate to
11631 <literal>CREATE</literal>.
11632 </para>
11634 <para>
11635 <function>pg_has_role</function> checks whether a user
11636 can access a role in a particular way. The possibilities for its
11637 arguments are analogous to <function>has_table_privilege</function>.
11638 The desired access privilege type must evaluate to
11639 <literal>MEMBER</literal> or
11640 <literal>USAGE</literal>.
11641 <literal>MEMBER</literal> denotes direct or indirect membership in
11642 the role (that is, the right to do <command>SET ROLE</>), while
11643 <literal>USAGE</literal> denotes whether the privileges of the role
11644 are immediately available without doing <command>SET ROLE</>.
11645 </para>
11647 <para>
11648 To test whether a user holds a grant option on the privilege,
11649 append <literal>WITH GRANT OPTION</literal> to the privilege key
11650 word; for example <literal>'UPDATE WITH GRANT OPTION'</literal>.
11651 </para>
11653 <para>
11654 <xref linkend="functions-info-schema-table"> shows functions that
11655 determine whether a certain object is <firstterm>visible</> in the
11656 current schema search path. A table is said to be visible if its
11657 containing schema is in the search path and no table of the same
11658 name appears earlier in the search path. This is equivalent to the
11659 statement that the table can be referenced by name without explicit
11660 schema qualification. For example, to list the names of all
11661 visible tables:
11662 <programlisting>
11663 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
11664 </programlisting>
11665 </para>
11667 <table id="functions-info-schema-table">
11668 <title>Schema Visibility Inquiry Functions</title>
11669 <tgroup cols="3">
11670 <thead>
11671 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11672 </thead>
11674 <tbody>
11675 <row>
11676 <entry><literal><function>pg_conversion_is_visible</function>(<parameter>conversion_oid</parameter>)</literal>
11677 </entry>
11678 <entry><type>boolean</type></entry>
11679 <entry>is conversion visible in search path</entry>
11680 </row>
11681 <row>
11682 <entry><literal><function>pg_function_is_visible</function>(<parameter>function_oid</parameter>)</literal>
11683 </entry>
11684 <entry><type>boolean</type></entry>
11685 <entry>is function visible in search path</entry>
11686 </row>
11687 <row>
11688 <entry><literal><function>pg_operator_is_visible</function>(<parameter>operator_oid</parameter>)</literal>
11689 </entry>
11690 <entry><type>boolean</type></entry>
11691 <entry>is operator visible in search path</entry>
11692 </row>
11693 <row>
11694 <entry><literal><function>pg_opclass_is_visible</function>(<parameter>opclass_oid</parameter>)</literal>
11695 </entry>
11696 <entry><type>boolean</type></entry>
11697 <entry>is operator class visible in search path</entry>
11698 </row>
11699 <row>
11700 <entry><literal><function>pg_table_is_visible</function>(<parameter>table_oid</parameter>)</literal>
11701 </entry>
11702 <entry><type>boolean</type></entry>
11703 <entry>is table visible in search path</entry>
11704 </row>
11705 <row>
11706 <entry><literal><function>pg_type_is_visible</function>(<parameter>type_oid</parameter>)</literal>
11707 </entry>
11708 <entry><type>boolean</type></entry>
11709 <entry>is type (or domain) visible in search path</entry>
11710 </row>
11711 </tbody>
11712 </tgroup>
11713 </table>
11715 <indexterm>
11716 <primary>pg_conversion_is_visible</primary>
11717 </indexterm>
11718 <indexterm>
11719 <primary>pg_function_is_visible</primary>
11720 </indexterm>
11721 <indexterm>
11722 <primary>pg_operator_is_visible</primary>
11723 </indexterm>
11724 <indexterm>
11725 <primary>pg_opclass_is_visible</primary>
11726 </indexterm>
11727 <indexterm>
11728 <primary>pg_table_is_visible</primary>
11729 </indexterm>
11730 <indexterm>
11731 <primary>pg_type_is_visible</primary>
11732 </indexterm>
11734 <para>
11735 <function>pg_conversion_is_visible</function>,
11736 <function>pg_function_is_visible</function>,
11737 <function>pg_operator_is_visible</function>,
11738 <function>pg_opclass_is_visible</function>,
11739 <function>pg_table_is_visible</function>, and
11740 <function>pg_type_is_visible</function> perform the visibility check for
11741 conversions, functions, operators, operator classes, tables, and
11742 types. Note that <function>pg_table_is_visible</function> can also be used
11743 with views, indexes and sequences; <function>pg_type_is_visible</function>
11744 can also be used with domains. For functions and operators, an object in
11745 the search path is visible if there is no object of the same name
11746 <emphasis>and argument data type(s)</> earlier in the path. For operator
11747 classes, both name and associated index access method are considered.
11748 </para>
11750 <para>
11751 All these functions require object OIDs to identify the object to be
11752 checked. If you want to test an object by name, it is convenient to use
11753 the OID alias types (<type>regclass</>, <type>regtype</>,
11754 <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
11755 or <type>regdictionary</>),
11756 for example:
11757 <programlisting>
11758 SELECT pg_type_is_visible('myschema.widget'::regtype);
11759 </programlisting>
11760 Note that it would not make much sense to test an unqualified name in
11761 this way &mdash; if the name can be recognized at all, it must be visible.
11762 </para>
11764 <indexterm>
11765 <primary>format_type</primary>
11766 </indexterm>
11768 <indexterm>
11769 <primary>pg_get_viewdef</primary>
11770 </indexterm>
11772 <indexterm>
11773 <primary>pg_get_ruledef</primary>
11774 </indexterm>
11776 <indexterm>
11777 <primary>pg_get_indexdef</primary>
11778 </indexterm>
11780 <indexterm>
11781 <primary>pg_get_triggerdef</primary>
11782 </indexterm>
11784 <indexterm>
11785 <primary>pg_get_constraintdef</primary>
11786 </indexterm>
11788 <indexterm>
11789 <primary>pg_get_expr</primary>
11790 </indexterm>
11792 <indexterm>
11793 <primary>pg_get_userbyid</primary>
11794 </indexterm>
11796 <indexterm>
11797 <primary>pg_get_serial_sequence</primary>
11798 </indexterm>
11800 <indexterm>
11801 <primary>pg_tablespace_databases</primary>
11802 </indexterm>
11804 <para>
11805 <xref linkend="functions-info-catalog-table"> lists functions that
11806 extract information from the system catalogs.
11807 </para>
11809 <table id="functions-info-catalog-table">
11810 <title>System Catalog Information Functions</title>
11811 <tgroup cols="3">
11812 <thead>
11813 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11814 </thead>
11816 <tbody>
11817 <row>
11818 <entry><literal><function>format_type</function>(<parameter>type_oid</parameter>, <parameter>typemod</>)</literal></entry>
11819 <entry><type>text</type></entry>
11820 <entry>get SQL name of a data type</entry>
11821 </row>
11822 <row>
11823 <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>)</literal></entry>
11824 <entry><type>text</type></entry>
11825 <entry>get definition of a constraint</entry>
11826 </row>
11827 <row>
11828 <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11829 <entry><type>text</type></entry>
11830 <entry>get definition of a constraint</entry>
11831 </row>
11832 <row>
11833 <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>)</literal></entry>
11834 <entry><type>text</type></entry>
11835 <entry>decompile internal form of an expression, assuming that any Vars
11836 in it refer to the relation indicated by the second parameter</entry>
11837 </row>
11838 <row>
11839 <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</literal></entry>
11840 <entry><type>text</type></entry>
11841 <entry>decompile internal form of an expression, assuming that any Vars
11842 in it refer to the relation indicated by the second parameter</entry>
11843 </row>
11844 <row>
11845 <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
11846 <entry><type>text</type></entry>
11847 <entry>get <command>CREATE INDEX</> command for index</entry>
11848 </row>
11849 <row>
11850 <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</literal></entry>
11851 <entry><type>text</type></entry>
11852 <entry>get <command>CREATE INDEX</> command for index,
11853 or definition of just one index column when
11854 <parameter>column_no</> is not zero</entry>
11855 </row>
11856 <row>
11857 <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>)</literal></entry>
11858 <entry><type>text</type></entry>
11859 <entry>get <command>CREATE RULE</> command for rule</entry>
11860 </row>
11861 <row>
11862 <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11863 <entry><type>text</type></entry>
11864 <entry>get <command>CREATE RULE</> command for rule</entry>
11865 </row>
11866 <row>
11867 <entry><literal><function>pg_get_serial_sequence</function>(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</literal></entry>
11868 <entry><type>text</type></entry>
11869 <entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
11870 uses</entry>
11871 </row>
11872 <row>
11873 <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
11874 <entry><type>text</type></entry>
11875 <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
11876 </row>
11877 <row>
11878 <entry><literal><function>pg_get_userbyid</function>(<parameter>roleid</parameter>)</literal></entry>
11879 <entry><type>name</type></entry>
11880 <entry>get role name with given ID</entry>
11881 </row>
11882 <row>
11883 <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>)</literal></entry>
11884 <entry><type>text</type></entry>
11885 <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
11886 </row>
11887 <row>
11888 <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</literal></entry>
11889 <entry><type>text</type></entry>
11890 <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
11891 </row>
11892 <row>
11893 <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>)</literal></entry>
11894 <entry><type>text</type></entry>
11895 <entry>get underlying <command>SELECT</command> command for view</entry>
11896 </row>
11897 <row>
11898 <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
11899 <entry><type>text</type></entry>
11900 <entry>get underlying <command>SELECT</command> command for view</entry>
11901 </row>
11902 <row>
11903 <entry><literal><function>pg_tablespace_databases</function>(<parameter>tablespace_oid</parameter>)</literal></entry>
11904 <entry><type>setof oid</type></entry>
11905 <entry>get the set of database OIDs that have objects in the tablespace</entry>
11906 </row>
11907 </tbody>
11908 </tgroup>
11909 </table>
11911 <para>
11912 <function>format_type</function> returns the SQL name of a data type that
11913 is identified by its type OID and possibly a type modifier. Pass NULL
11914 for the type modifier if no specific modifier is known.
11915 </para>
11917 <para>
11918 <function>pg_get_constraintdef</function>,
11919 <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
11920 and <function>pg_get_triggerdef</function>, respectively reconstruct the
11921 creating command for a constraint, index, rule, or trigger. (Note that this
11922 is a decompiled reconstruction, not the original text of the command.)
11923 <function>pg_get_expr</function> decompiles the internal form of an
11924 individual expression, such as the default value for a column. It can be
11925 useful when examining the contents of system catalogs.
11926 <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
11927 query that defines a view. Most of these functions come in two variants,
11928 one of which can optionally <quote>pretty-print</> the result. The
11929 pretty-printed format is more readable, but the default format is more
11930 likely to be interpreted the same way by future versions of
11931 <productname>PostgreSQL</>; avoid using pretty-printed output for dump
11932 purposes. Passing <literal>false</> for the pretty-print parameter yields
11933 the same result as the variant that does not have the parameter at all.
11934 </para>
11936 <para>
11937 <function>pg_get_serial_sequence</function> returns the name of the
11938 sequence associated with a column, or NULL if no sequence is associated
11939 with the column. The first input parameter is a table name with
11940 optional schema, and the second parameter is a column name. Because
11941 the first parameter is potentially a schema and table, it is not treated
11942 as a double-quoted identifier, meaning it is lowercased by default,
11943 while the second parameter, being just a column name, is treated as
11944 double-quoted and has its case preserved. The function returns a value
11945 suitably formatted for passing to the sequence functions (see <xref
11946 linkend="functions-sequence">). This association can be modified or
11947 removed with <command>ALTER SEQUENCE OWNED BY</>. (The function
11948 probably should have been called
11949 <function>pg_get_owned_sequence</function>; its name reflects the fact
11950 that it's typically used with <type>serial</> or <type>bigserial</>
11951 columns.)
11952 </para>
11954 <para>
11955 <function>pg_get_userbyid</function> extracts a role's name given
11956 its OID.
11957 </para>
11959 <para>
11960 <function>pg_tablespace_databases</function> allows a tablespace to be
11961 examined. It returns the set of OIDs of databases that have objects stored
11962 in the tablespace. If this function returns any rows, the tablespace is not
11963 empty and cannot be dropped. To display the specific objects populating the
11964 tablespace, you will need to connect to the databases identified by
11965 <function>pg_tablespace_databases</function> and query their
11966 <structname>pg_class</> catalogs.
11967 </para>
11969 <indexterm>
11970 <primary>col_description</primary>
11971 </indexterm>
11973 <indexterm>
11974 <primary>obj_description</primary>
11975 </indexterm>
11977 <indexterm>
11978 <primary>shobj_description</primary>
11979 </indexterm>
11981 <indexterm>
11982 <primary>comment</primary>
11983 <secondary sortas="database objects">about database objects</secondary>
11984 </indexterm>
11986 <para>
11987 The functions shown in <xref linkend="functions-info-comment-table">
11988 extract comments previously stored with the <xref linkend="sql-comment"
11989 endterm="sql-comment-title"> command. A null value is returned if no
11990 comment could be found matching the specified parameters.
11991 </para>
11993 <table id="functions-info-comment-table">
11994 <title>Comment Information Functions</title>
11995 <tgroup cols="3">
11996 <thead>
11997 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11998 </thead>
12000 <tbody>
12001 <row>
12002 <entry><literal><function>col_description</function>(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</literal></entry>
12003 <entry><type>text</type></entry>
12004 <entry>get comment for a table column</entry>
12005 </row>
12006 <row>
12007 <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12008 <entry><type>text</type></entry>
12009 <entry>get comment for a database object</entry>
12010 </row>
12011 <row>
12012 <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>)</literal></entry>
12013 <entry><type>text</type></entry>
12014 <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
12015 </row>
12016 <row>
12017 <entry><literal><function>shobj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12018 <entry><type>text</type></entry>
12019 <entry>get comment for a shared database object</entry>
12020 </row>
12021 </tbody>
12022 </tgroup>
12023 </table>
12025 <para>
12026 <function>col_description</function> returns the comment for a table column,
12027 which is specified by the OID of its table and its column number.
12028 <function>obj_description</function> cannot be used for table columns since
12029 columns do not have OIDs of their own.
12030 </para>
12032 <para>
12033 The two-parameter form of <function>obj_description</function> returns the
12034 comment for a database object specified by its OID and the name of the
12035 containing system catalog. For example,
12036 <literal>obj_description(123456,'pg_class')</literal>
12037 would retrieve the comment for a table with OID 123456.
12038 The one-parameter form of <function>obj_description</function> requires only
12039 the object OID. It is now deprecated since there is no guarantee that
12040 OIDs are unique across different system catalogs; therefore, the wrong
12041 comment could be returned.
12042 </para>
12044 <para>
12045 <function>shobj_description</function> is used just like
12046 <function>obj_description</function> only that it is used for retrieving
12047 comments on shared objects. Some system catalogs are global to all
12048 databases within each cluster and their descriptions are stored globally
12049 as well.
12050 </para>
12052 <indexterm>
12053 <primary>txid_current</primary>
12054 </indexterm>
12056 <indexterm>
12057 <primary>txid_current_snapshot</primary>
12058 </indexterm>
12060 <indexterm>
12061 <primary>txid_snapshot_xmin</primary>
12062 </indexterm>
12064 <indexterm>
12065 <primary>txid_snapshot_xmax</primary>
12066 </indexterm>
12068 <indexterm>
12069 <primary>txid_snapshot_xip</primary>
12070 </indexterm>
12072 <indexterm>
12073 <primary>txid_visible_in_snapshot</primary>
12074 </indexterm>
12076 <para>
12077 The functions shown in <xref linkend="functions-txid-snapshot">
12078 export server internal transaction info to user level.
12079 </para>
12081 <table id="functions-txid-snapshot">
12082 <title>Transaction IDs and snapshots</title>
12083 <tgroup cols="3">
12084 <thead>
12085 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12086 </thead>
12088 <tbody>
12089 <row>
12090 <entry><literal><function>txid_current</function>()</literal></entry>
12091 <entry><type>bigint</type></entry>
12092 <entry>get current transaction ID</entry>
12093 </row>
12094 <row>
12095 <entry><literal><function>txid_current_snapshot</function>()</literal></entry>
12096 <entry><type>txid_snapshot</type></entry>
12097 <entry>get current snapshot</entry>
12098 </row>
12099 <row>
12100 <entry><literal><function>txid_snapshot_xmin</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12101 <entry><type>bigint</type></entry>
12102 <entry>get xmin of snapshot</entry>
12103 </row>
12104 <row>
12105 <entry><literal><function>txid_snapshot_xmax</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12106 <entry><type>bigint</type></entry>
12107 <entry>get xmax of snapshot</entry>
12108 </row>
12109 <row>
12110 <entry><literal><function>txid_snapshot_xip</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12111 <entry><type>setof bigint</type></entry>
12112 <entry>get in-progress transaction IDs in snapshot</entry>
12113 </row>
12114 <row>
12115 <entry><literal><function>txid_visible_in_snapshot</function>(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</literal></entry>
12116 <entry><type>boolean</type></entry>
12117 <entry>is transaction ID visible in snapshot?</entry>
12118 </row>
12119 </tbody>
12120 </tgroup>
12121 </table>
12123 <para>
12124 The internal transaction ID type (<type>xid</>) is 32 bits wide and so
12125 it wraps around every 4 billion transactions. However, these functions
12126 export a 64-bit format that is extended with an <quote>epoch</> counter
12127 so that it will not wrap around for the life of an installation.
12128 </para>
12129 </sect1>
12131 <sect1 id="functions-admin">
12132 <title>System Administration Functions</title>
12134 <para>
12135 <xref linkend="functions-admin-set-table"> shows the functions
12136 available to query and alter run-time configuration parameters.
12137 </para>
12139 <table id="functions-admin-set-table">
12140 <title>Configuration Settings Functions</title>
12141 <tgroup cols="3">
12142 <thead>
12143 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12144 </thead>
12146 <tbody>
12147 <row>
12148 <entry>
12149 <literal><function>current_setting</function>(<parameter>setting_name</parameter>)</literal>
12150 </entry>
12151 <entry><type>text</type></entry>
12152 <entry>current value of setting</entry>
12153 </row>
12154 <row>
12155 <entry>
12156 <literal><function>set_config(<parameter>setting_name</parameter>,
12157 <parameter>new_value</parameter>,
12158 <parameter>is_local</parameter>)</function></literal>
12159 </entry>
12160 <entry><type>text</type></entry>
12161 <entry>set parameter and return new value</entry>
12162 </row>
12163 </tbody>
12164 </tgroup>
12165 </table>
12167 <indexterm>
12168 <primary>SET</primary>
12169 </indexterm>
12171 <indexterm>
12172 <primary>SHOW</primary>
12173 </indexterm>
12175 <indexterm>
12176 <primary>configuration</primary>
12177 <secondary sortas="server">of the server</secondary>
12178 <tertiary>functions</tertiary>
12179 </indexterm>
12181 <para>
12182 The function <function>current_setting</function> yields the
12183 current value of the setting <parameter>setting_name</parameter>.
12184 It corresponds to the <acronym>SQL</acronym> command
12185 <command>SHOW</command>. An example:
12186 <programlisting>
12187 SELECT current_setting('datestyle');
12189 current_setting
12190 -----------------
12191 ISO, MDY
12192 (1 row)
12193 </programlisting>
12194 </para>
12196 <para>
12197 <function>set_config</function> sets the parameter
12198 <parameter>setting_name</parameter> to
12199 <parameter>new_value</parameter>. If
12200 <parameter>is_local</parameter> is <literal>true</literal>, the
12201 new value will only apply to the current transaction. If you want
12202 the new value to apply for the current session, use
12203 <literal>false</literal> instead. The function corresponds to the
12204 SQL command <command>SET</command>. An example:
12205 <programlisting>
12206 SELECT set_config('log_statement_stats', 'off', false);
12208 set_config
12209 ------------
12211 (1 row)
12212 </programlisting>
12213 </para>
12215 <indexterm>
12216 <primary>pg_cancel_backend</primary>
12217 </indexterm>
12218 <indexterm>
12219 <primary>pg_reload_conf</primary>
12220 </indexterm>
12221 <indexterm>
12222 <primary>pg_rotate_logfile</primary>
12223 </indexterm>
12225 <indexterm>
12226 <primary>signal</primary>
12227 <secondary sortas="backend">backend processes</secondary>
12228 </indexterm>
12230 <para>
12231 The functions shown in <xref
12232 linkend="functions-admin-signal-table"> send control signals to
12233 other server processes. Use of these functions is restricted
12234 to superusers.
12235 </para>
12237 <table id="functions-admin-signal-table">
12238 <title>Server Signalling Functions</title>
12239 <tgroup cols="3">
12240 <thead>
12241 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12242 </row>
12243 </thead>
12245 <tbody>
12246 <row>
12247 <entry>
12248 <literal><function>pg_cancel_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12249 </entry>
12250 <entry><type>boolean</type></entry>
12251 <entry>Cancel a backend's current query</entry>
12252 </row>
12253 <row>
12254 <entry>
12255 <literal><function>pg_reload_conf</function>()</literal>
12256 </entry>
12257 <entry><type>boolean</type></entry>
12258 <entry>Cause server processes to reload their configuration files</entry>
12259 </row>
12260 <row>
12261 <entry>
12262 <literal><function>pg_rotate_logfile</function>()</literal>
12263 </entry>
12264 <entry><type>boolean</type></entry>
12265 <entry>Rotate server's log file</entry>
12266 </row>
12267 </tbody>
12268 </tgroup>
12269 </table>
12271 <para>
12272 Each of these functions returns <literal>true</literal> if
12273 successful and <literal>false</literal> otherwise.
12274 </para>
12276 <para>
12277 <function>pg_cancel_backend</> sends a query cancel
12278 (<systemitem>SIGINT</>) signal to a backend process identified by
12279 process ID. The process ID of an active backend can be found from
12280 the <structfield>procpid</structfield> column in the
12281 <structname>pg_stat_activity</structname> view, or by listing the
12282 <command>postgres</command> processes on the server with
12283 <application>ps</>.
12284 </para>
12286 <para>
12287 <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
12288 to the server, causing the configuration files
12289 to be reloaded by all server processes.
12290 </para>
12292 <para>
12293 <function>pg_rotate_logfile</> signals the log-file manager to switch
12294 to a new output file immediately. This works only when the built-in
12295 log collector is running, since otherwise there is no log-file manager
12296 subprocess.
12297 </para>
12299 <indexterm>
12300 <primary>pg_start_backup</primary>
12301 </indexterm>
12302 <indexterm>
12303 <primary>pg_stop_backup</primary>
12304 </indexterm>
12305 <indexterm>
12306 <primary>pg_switch_xlog</primary>
12307 </indexterm>
12308 <indexterm>
12309 <primary>pg_current_xlog_location</primary>
12310 </indexterm>
12311 <indexterm>
12312 <primary>pg_current_xlog_insert_location</primary>
12313 </indexterm>
12314 <indexterm>
12315 <primary>pg_xlogfile_name_offset</primary>
12316 </indexterm>
12317 <indexterm>
12318 <primary>pg_xlogfile_name</primary>
12319 </indexterm>
12320 <indexterm>
12321 <primary>backup</primary>
12322 </indexterm>
12324 <para>
12325 The functions shown in <xref
12326 linkend="functions-admin-backup-table"> assist in making on-line backups.
12327 Use of the first three functions is restricted to superusers.
12328 </para>
12330 <table id="functions-admin-backup-table">
12331 <title>Backup Control Functions</title>
12332 <tgroup cols="3">
12333 <thead>
12334 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12335 </row>
12336 </thead>
12338 <tbody>
12339 <row>
12340 <entry>
12341 <literal><function>pg_start_backup</function>(<parameter>label</> <type>text</>)</literal>
12342 </entry>
12343 <entry><type>text</type></entry>
12344 <entry>Set up for performing on-line backup</entry>
12345 </row>
12346 <row>
12347 <entry>
12348 <literal><function>pg_stop_backup</function>()</literal>
12349 </entry>
12350 <entry><type>text</type></entry>
12351 <entry>Finish performing on-line backup</entry>
12352 </row>
12353 <row>
12354 <entry>
12355 <literal><function>pg_switch_xlog</function>()</literal>
12356 </entry>
12357 <entry><type>text</type></entry>
12358 <entry>Force switch to a new transaction log file</entry>
12359 </row>
12360 <row>
12361 <entry>
12362 <literal><function>pg_current_xlog_location</function>()</literal>
12363 </entry>
12364 <entry><type>text</type></entry>
12365 <entry>Get current transaction log write location</entry>
12366 </row>
12367 <row>
12368 <entry>
12369 <literal><function>pg_current_xlog_insert_location</function>()</literal>
12370 </entry>
12371 <entry><type>text</type></entry>
12372 <entry>Get current transaction log insert location</entry>
12373 </row>
12374 <row>
12375 <entry>
12376 <literal><function>pg_xlogfile_name_offset</function>(<parameter>location</> <type>text</>)</literal>
12377 </entry>
12378 <entry><type>text</>, <type>integer</></entry>
12379 <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
12380 </row>
12381 <row>
12382 <entry>
12383 <literal><function>pg_xlogfile_name</function>(<parameter>location</> <type>text</>)</literal>
12384 </entry>
12385 <entry><type>text</type></entry>
12386 <entry>Convert transaction log location string to file name</entry>
12387 </row>
12388 </tbody>
12389 </tgroup>
12390 </table>
12392 <para>
12393 <function>pg_start_backup</> accepts a single parameter which is an
12394 arbitrary user-defined label for the backup. (Typically this would be
12395 the name under which the backup dump file will be stored.) The function
12396 writes a backup label file into the database cluster's data directory,
12397 and then returns the backup's starting transaction log location as text. The user
12398 need not pay any attention to this result value, but it is provided in
12399 case it is of use.
12400 <programlisting>
12401 postgres=# select pg_start_backup('label_goes_here');
12402 pg_start_backup
12403 -----------------
12404 0/D4445B8
12405 (1 row)
12406 </programlisting>
12407 </para>
12409 <para>
12410 <function>pg_stop_backup</> removes the label file created by
12411 <function>pg_start_backup</>, and instead creates a backup history file in
12412 the transaction log archive area. The history file includes the label given to
12413 <function>pg_start_backup</>, the starting and ending transaction log locations for
12414 the backup, and the starting and ending times of the backup. The return
12415 value is the backup's ending transaction log location (which again might be of little
12416 interest). After noting the ending location, the current transaction log insertion
12417 point is automatically advanced to the next transaction log file, so that the
12418 ending transaction log file can be archived immediately to complete the backup.
12419 </para>
12421 <para>
12422 <function>pg_switch_xlog</> moves to the next transaction log file, allowing the
12423 current file to be archived (assuming you are using continuous archiving).
12424 The result is the ending transaction log location within the just-completed transaction log file.
12425 If there has been no transaction log activity since the last transaction log switch,
12426 <function>pg_switch_xlog</> does nothing and returns the end location
12427 of the previous transaction log file.
12428 </para>
12430 <para>
12431 <function>pg_current_xlog_location</> displays the current transaction log write
12432 location in the same format used by the above functions. Similarly,
12433 <function>pg_current_xlog_insert_location</> displays the current transaction log
12434 insertion point. The insertion point is the <quote>logical</> end
12435 of the transaction log
12436 at any instant, while the write location is the end of what has actually
12437 been written out from the server's internal buffers. The write location
12438 is the end of what can be examined from outside the server, and is usually
12439 what you want if you are interested in archiving partially-complete transaction log
12440 files. The insertion point is made available primarily for server
12441 debugging purposes. These are both read-only operations and do not
12442 require superuser permissions.
12443 </para>
12445 <para>
12446 You can use <function>pg_xlogfile_name_offset</> to extract the
12447 corresponding transaction log file name and byte offset from the results of any of the
12448 above functions. For example:
12449 <programlisting>
12450 postgres=# select * from pg_xlogfile_name_offset(pg_stop_backup());
12451 file_name | file_offset
12452 --------------------------+-------------
12453 00000001000000000000000D | 4039624
12454 (1 row)
12455 </programlisting>
12456 Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
12457 When the given transaction log location is exactly at a transaction log file boundary, both
12458 these functions return the name of the preceding transaction log file.
12459 This is usually the desired behavior for managing transaction log archiving
12460 behavior, since the preceding file is the last one that currently
12461 needs to be archived.
12462 </para>
12464 <para>
12465 For details about proper usage of these functions, see
12466 <xref linkend="continuous-archiving">.
12467 </para>
12469 <para>
12470 The functions shown in <xref linkend="functions-admin-dbsize"> calculate
12471 the actual disk space usage of database objects.
12472 </para>
12474 <indexterm>
12475 <primary>pg_column_size</primary>
12476 </indexterm>
12477 <indexterm>
12478 <primary>pg_database_size</primary>
12479 </indexterm>
12480 <indexterm>
12481 <primary>pg_relation_size</primary>
12482 </indexterm>
12483 <indexterm>
12484 <primary>pg_size_pretty</primary>
12485 </indexterm>
12486 <indexterm>
12487 <primary>pg_tablespace_size</primary>
12488 </indexterm>
12489 <indexterm>
12490 <primary>pg_total_relation_size</primary>
12491 </indexterm>
12493 <table id="functions-admin-dbsize">
12494 <title>Database Object Size Functions</title>
12495 <tgroup cols="3">
12496 <thead>
12497 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12498 </row>
12499 </thead>
12501 <tbody>
12502 <row>
12503 <entry><function>pg_column_size</function>(<type>any</type>)</entry>
12504 <entry><type>int</type></entry>
12505 <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
12506 </row>
12507 <row>
12508 <entry>
12509 <literal><function>pg_database_size</function>(<type>oid</type>)</literal>
12510 </entry>
12511 <entry><type>bigint</type></entry>
12512 <entry>Disk space used by the database with the specified OID</entry>
12513 </row>
12514 <row>
12515 <entry>
12516 <literal><function>pg_database_size</function>(<type>name</type>)</literal>
12517 </entry>
12518 <entry><type>bigint</type></entry>
12519 <entry>Disk space used by the database with the specified name</entry>
12520 </row>
12521 <row>
12522 <entry>
12523 <literal><function>pg_relation_size</function>(<type>oid</type>)</literal>
12524 </entry>
12525 <entry><type>bigint</type></entry>
12526 <entry>Disk space used by the table or index with the specified OID</entry>
12527 </row>
12528 <row>
12529 <entry>
12530 <literal><function>pg_relation_size</function>(<type>text</type>)</literal>
12531 </entry>
12532 <entry><type>bigint</type></entry>
12533 <entry>
12534 Disk space used by the table or index with the specified name.
12535 The table name can be qualified with a schema name
12536 </entry>
12537 </row>
12538 <row>
12539 <entry>
12540 <literal><function>pg_size_pretty</function>(<type>bigint</type>)</literal>
12541 </entry>
12542 <entry><type>text</type></entry>
12543 <entry>Converts a size in bytes into a human-readable format with size units</entry>
12544 </row>
12545 <row>
12546 <entry>
12547 <literal><function>pg_tablespace_size</function>(<type>oid</type>)</literal>
12548 </entry>
12549 <entry><type>bigint</type></entry>
12550 <entry>Disk space used by the tablespace with the specified OID</entry>
12551 </row>
12552 <row>
12553 <entry>
12554 <literal><function>pg_tablespace_size</function>(<type>name</type>)</literal>
12555 </entry>
12556 <entry><type>bigint</type></entry>
12557 <entry>Disk space used by the tablespace with the specified name</entry>
12558 </row>
12559 <row>
12560 <entry>
12561 <literal><function>pg_total_relation_size</function>(<type>oid</type>)</literal>
12562 </entry>
12563 <entry><type>bigint</type></entry>
12564 <entry>
12565 Total disk space used by the table with the specified OID,
12566 including indexes and toasted data
12567 </entry>
12568 </row>
12569 <row>
12570 <entry>
12571 <literal><function>pg_total_relation_size</function>(<type>text</type>)</literal>
12572 </entry>
12573 <entry><type>bigint</type></entry>
12574 <entry>
12575 Total disk space used by the table with the specified name,
12576 including indexes and toasted data. The table name can be
12577 qualified with a schema name
12578 </entry>
12579 </row>
12580 </tbody>
12581 </tgroup>
12582 </table>
12584 <para>
12585 <function>pg_column_size</> shows the space used to store any individual
12586 data value.
12587 </para>
12589 <para>
12590 <function>pg_database_size</function> and <function>pg_tablespace_size</>
12591 accept the OID or name of a database or tablespace, and return the total
12592 disk space used therein.
12593 </para>
12595 <para>
12596 <function>pg_relation_size</> accepts the OID or name of a table, index or
12597 toast table, and returns the size in bytes.
12598 </para>
12600 <para>
12601 <function>pg_size_pretty</> can be used to format the result of one of
12602 the other functions in a human-readable way, using kB, MB, GB or TB as
12603 appropriate.
12604 </para>
12606 <para>
12607 <function>pg_total_relation_size</> accepts the OID or name of a
12608 table or toast table, and returns the size in bytes of the data
12609 and all associated indexes and toast tables.
12610 </para>
12612 <para>
12613 The functions shown in <xref
12614 linkend="functions-admin-genfile"> provide native file access to
12615 files on the machine hosting the server. Only files within the
12616 database cluster directory and the <varname>log_directory</> can be
12617 accessed. Use a relative path for files within the cluster directory,
12618 and a path matching the <varname>log_directory</> configuration setting
12619 for log files. Use of these functions is restricted to superusers.
12620 </para>
12622 <table id="functions-admin-genfile">
12623 <title>Generic File Access Functions</title>
12624 <tgroup cols="3">
12625 <thead>
12626 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12627 </row>
12628 </thead>
12630 <tbody>
12631 <row>
12632 <entry>
12633 <literal><function>pg_ls_dir</function>(<parameter>dirname</> <type>text</>)</literal>
12634 </entry>
12635 <entry><type>setof text</type></entry>
12636 <entry>List the contents of a directory</entry>
12637 </row>
12638 <row>
12639 <entry>
12640 <literal><function>pg_read_file</function>(<parameter>filename</> <type>text</>, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>)</literal>
12641 </entry>
12642 <entry><type>text</type></entry>
12643 <entry>Return the contents of a text file</entry>
12644 </row>
12645 <row>
12646 <entry>
12647 <literal><function>pg_stat_file</function>(<parameter>filename</> <type>text</>)</literal>
12648 </entry>
12649 <entry><type>record</type></entry>
12650 <entry>Return information about a file</entry>
12651 </row>
12652 </tbody>
12653 </tgroup>
12654 </table>
12656 <indexterm>
12657 <primary>pg_ls_dir</primary>
12658 </indexterm>
12659 <para>
12660 <function>pg_ls_dir</> returns all the names in the specified
12661 directory, except the special entries <quote><literal>.</></> and
12662 <quote><literal>..</></>.
12663 </para>
12665 <indexterm>
12666 <primary>pg_read_file</primary>
12667 </indexterm>
12668 <para>
12669 <function>pg_read_file</> returns part of a text file, starting
12670 at the given <parameter>offset</>, returning at most <parameter>length</>
12671 bytes (less if the end of file is reached first). If <parameter>offset</>
12672 is negative, it is relative to the end of the file.
12673 </para>
12675 <indexterm>
12676 <primary>pg_stat_file</primary>
12677 </indexterm>
12678 <para>
12679 <function>pg_stat_file</> returns a record containing the file
12680 size, last accessed time stamp, last modified time stamp,
12681 last file status change time stamp (Unix platforms only),
12682 file creation time stamp (Windows only), and a <type>boolean</type>
12683 indicating if it is a directory. Typical usages include:
12684 <programlisting>
12685 SELECT * FROM pg_stat_file('filename');
12686 SELECT (pg_stat_file('filename')).modification;
12687 </programlisting>
12688 </para>
12690 <para>
12691 The functions shown in <xref linkend="functions-advisory-locks"> manage
12692 advisory locks. For details about proper usage of these functions, see
12693 <xref linkend="advisory-locks">.
12694 </para>
12696 <table id="functions-advisory-locks">
12697 <title>Advisory Lock Functions</title>
12698 <tgroup cols="3">
12699 <thead>
12700 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12701 </row>
12702 </thead>
12704 <tbody>
12705 <row>
12706 <entry>
12707 <literal><function>pg_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
12708 </entry>
12709 <entry><type>void</type></entry>
12710 <entry>Obtain exclusive advisory lock</entry>
12711 </row>
12712 <row>
12713 <entry>
12714 <literal><function>pg_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12715 </entry>
12716 <entry><type>void</type></entry>
12717 <entry>Obtain exclusive advisory lock</entry>
12718 </row>
12720 <row>
12721 <entry>
12722 <literal><function>pg_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12723 </entry>
12724 <entry><type>void</type></entry>
12725 <entry>Obtain shared advisory lock</entry>
12726 </row>
12727 <row>
12728 <entry>
12729 <literal><function>pg_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12730 </entry>
12731 <entry><type>void</type></entry>
12732 <entry>Obtain shared advisory lock</entry>
12733 </row>
12735 <row>
12736 <entry>
12737 <literal><function>pg_try_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
12738 </entry>
12739 <entry><type>boolean</type></entry>
12740 <entry>Obtain exclusive advisory lock if available</entry>
12741 </row>
12742 <row>
12743 <entry>
12744 <literal><function>pg_try_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12745 </entry>
12746 <entry><type>boolean</type></entry>
12747 <entry>Obtain exclusive advisory lock if available</entry>
12748 </row>
12750 <row>
12751 <entry>
12752 <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12753 </entry>
12754 <entry><type>boolean</type></entry>
12755 <entry>Obtain shared advisory lock if available</entry>
12756 </row>
12757 <row>
12758 <entry>
12759 <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12760 </entry>
12761 <entry><type>boolean</type></entry>
12762 <entry>Obtain shared advisory lock if available</entry>
12763 </row>
12765 <row>
12766 <entry>
12767 <literal><function>pg_advisory_unlock</function>(<parameter>key</> <type>bigint</>)</literal>
12768 </entry>
12769 <entry><type>boolean</type></entry>
12770 <entry>Release an exclusive advisory lock</entry>
12771 </row>
12772 <row>
12773 <entry>
12774 <literal><function>pg_advisory_unlock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12775 </entry>
12776 <entry><type>boolean</type></entry>
12777 <entry>Release an exclusive advisory lock</entry>
12778 </row>
12780 <row>
12781 <entry>
12782 <literal><function>pg_advisory_unlock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
12783 </entry>
12784 <entry><type>boolean</type></entry>
12785 <entry>Release a shared advisory lock</entry>
12786 </row>
12787 <row>
12788 <entry>
12789 <literal><function>pg_advisory_unlock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
12790 </entry>
12791 <entry><type>boolean</type></entry>
12792 <entry>Release a shared advisory lock</entry>
12793 </row>
12795 <row>
12796 <entry>
12797 <literal><function>pg_advisory_unlock_all</function>()</literal>
12798 </entry>
12799 <entry><type>void</type></entry>
12800 <entry>Release all advisory locks held by the current session</entry>
12801 </row>
12803 </tbody>
12804 </tgroup>
12805 </table>
12807 <indexterm>
12808 <primary>pg_advisory_lock</primary>
12809 </indexterm>
12810 <para>
12811 <function>pg_advisory_lock</> locks an application-defined resource,
12812 which can be identified either by a single 64-bit key value or two
12813 32-bit key values (note that these two key spaces do not overlap). If
12814 another session already holds a lock on the same resource, the
12815 function will wait until the resource becomes available. The lock
12816 is exclusive. Multiple lock requests stack, so that if the same resource
12817 is locked three times it must be also unlocked three times to be
12818 released for other sessions' use.
12819 </para>
12821 <indexterm>
12822 <primary>pg_advisory_lock_shared</primary>
12823 </indexterm>
12824 <para>
12825 <function>pg_advisory_lock_shared</> works the same as
12826 <function>pg_advisory_lock</>,
12827 except the lock can be shared with other sessions requesting shared locks.
12828 Only would-be exclusive lockers are locked out.
12829 </para>
12831 <indexterm>
12832 <primary>pg_try_advisory_lock</primary>
12833 </indexterm>
12834 <para>
12835 <function>pg_try_advisory_lock</> is similar to
12836 <function>pg_advisory_lock</>, except the function will not wait for the
12837 lock to become available. It will either obtain the lock immediately and
12838 return <literal>true</>, or return <literal>false</> if the lock cannot be
12839 acquired now.
12840 </para>
12842 <indexterm>
12843 <primary>pg_try_advisory_lock_shared</primary>
12844 </indexterm>
12845 <para>
12846 <function>pg_try_advisory_lock_shared</> works the same as
12847 <function>pg_try_advisory_lock</>, except it attempts to acquire
12848 shared rather than exclusive lock.
12849 </para>
12851 <indexterm>
12852 <primary>pg_advisory_unlock</primary>
12853 </indexterm>
12854 <para>
12855 <function>pg_advisory_unlock</> will release a previously-acquired
12856 exclusive advisory lock. It
12857 will return <literal>true</> if the lock is successfully released.
12858 If the lock was in fact not held, it will return <literal>false</>,
12859 and in addition, an SQL warning will be raised by the server.
12860 </para>
12862 <indexterm>
12863 <primary>pg_advisory_unlock_shared</primary>
12864 </indexterm>
12865 <para>
12866 <function>pg_advisory_unlock_shared</> works the same as
12867 <function>pg_advisory_unlock</>,
12868 except to release a shared advisory lock.
12869 </para>
12871 <indexterm>
12872 <primary>pg_advisory_unlock_all</primary>
12873 </indexterm>
12874 <para>
12875 <function>pg_advisory_unlock_all</> will release all advisory locks
12876 held by the current session. (This function is implicitly invoked
12877 at session end, even if the client disconnects ungracefully.)
12878 </para>
12880 </sect1>
12882 </chapter>